Refactor and add tests
This commit is contained in:
parent
78c83c703b
commit
5ff8e37c61
2
.gitignore
vendored
Normal file
2
.gitignore
vendored
Normal file
@ -0,0 +1,2 @@
|
|||||||
|
data
|
||||||
|
output.txt
|
95
lints.sql
95
lints.sql
@ -1,6 +1,8 @@
|
|||||||
create temporary view tables as
|
create temporary view tables as
|
||||||
-- select * from sqlite_schema where type = 'table';
|
select l.*
|
||||||
select l.* from sqlite_schema s left join pragma_table_list l on s.name = l.name where s.type = 'table';
|
from sqlite_schema s
|
||||||
|
left join pragma_table_list l on s.name = l.name
|
||||||
|
where s.type = 'table';
|
||||||
|
|
||||||
|
|
||||||
create temporary view columns as
|
create temporary view columns as
|
||||||
@ -24,30 +26,23 @@ create temporary view columns as
|
|||||||
-- Require all fields to be not null, unless they are foreign keys
|
-- Require all fields to be not null, unless they are foreign keys
|
||||||
create temporary view lint_check__require_not_null as
|
create temporary view lint_check__require_not_null as
|
||||||
select 'Column should should be "not null"' as error_msg,
|
select 'Column should should be "not null"' as error_msg,
|
||||||
tables.name as table_name,
|
table_name,
|
||||||
table_info.name as column_name
|
column_name
|
||||||
from tables
|
from columns
|
||||||
join pragma_table_info(tables.name) as table_info
|
where columns."notnull" = 0
|
||||||
where not exists (
|
and fk_target_column is null
|
||||||
select 1 from pragma_foreign_key_list(tables.name) as fk
|
and is_primary_key = 0; -- primary keys are automatically not-null, but aren't listed as such in pragma_table_info
|
||||||
where fk."from" = table_info.name
|
|
||||||
)
|
|
||||||
and (table_info."notnull" = 0 and table_info.pk = 0);
|
|
||||||
|
|
||||||
|
|
||||||
-- Require all non-foreign-key, non-primary-key fields to have a default value
|
-- Require all non-foreign-key, non-primary-key fields to have a default value
|
||||||
create temporary view lint_check__require_default_values as
|
create temporary view lint_check__require_default_values as
|
||||||
select 'Column should have a default value' as error_msg,
|
select 'Column should have a default value' as error_msg,
|
||||||
tables.name as table_name,
|
table_name,
|
||||||
table_info.name as column_name
|
column_name
|
||||||
from tables
|
from columns
|
||||||
join pragma_table_info(tables.name) as table_info
|
where table_info.dflt_value is null
|
||||||
where table_info.pk = 0
|
and fk_target_column is null
|
||||||
and not exists (
|
and is_primary_key = 0;
|
||||||
select 1 from pragma_foreign_key_list(tables.name) as fk
|
|
||||||
where fk."from" = table_info.name
|
|
||||||
)
|
|
||||||
and table_info.dflt_value is null;
|
|
||||||
|
|
||||||
|
|
||||||
-- All tables should be STRICT (must specify column types; types must be int, integer, real, text,
|
-- All tables should be STRICT (must specify column types; types must be int, integer, real, text,
|
||||||
@ -58,18 +53,16 @@ create temporary view lint_check__require_strict as
|
|||||||
name as table_name,
|
name as table_name,
|
||||||
'' as column_name
|
'' as column_name
|
||||||
from tables
|
from tables
|
||||||
where strict = 0
|
where strict = 0;
|
||||||
and name not in ('sqlite_schema', 'sqlite_temp_schema');
|
|
||||||
|
|
||||||
|
|
||||||
-- Forbid use 'int' column types
|
-- Forbid use 'int' column types
|
||||||
create temporary view lint_check__forbid_int_type as
|
create temporary view lint_check__forbid_int_type as
|
||||||
select 'Column should use "integer" type instead of "int"' as error_msg,
|
select 'Column should use "integer" type instead of "int"' as error_msg,
|
||||||
tables.name as table_name,
|
table_name,
|
||||||
table_info.name as column_name
|
column_name
|
||||||
from tables
|
from columns
|
||||||
join pragma_table_info(tables.name) as table_info
|
where column_type like 'int';
|
||||||
where table_info.type like 'int';
|
|
||||||
|
|
||||||
|
|
||||||
-- tables must have a primary key; if it's rowid, it has to be named explicitly
|
-- tables must have a primary key; if it's rowid, it has to be named explicitly
|
||||||
@ -78,42 +71,35 @@ create temporary view lint_check__require_explicit_primary_key as
|
|||||||
tables.name as table_name,
|
tables.name as table_name,
|
||||||
'' as column_name
|
'' as column_name
|
||||||
from tables
|
from tables
|
||||||
where not exists (select name from pragma_table_info(tables.name) where pk != 0);
|
where not exists (select 1 from pragma_table_info(tables.name) where pk != 0);
|
||||||
|
|
||||||
|
|
||||||
-- columns referenced by foreign keys must have indexes
|
-- columns referenced by foreign keys must have indexes
|
||||||
create temporary view lint_check__require_indexes_for_foreign_keys as
|
create temporary view lint_check__require_indexes_for_foreign_keys as
|
||||||
with index_info as (
|
with index_info as (
|
||||||
select indexes.name as index_name,
|
select tables.name as table_name,
|
||||||
tables.name as table_name,
|
columns.name as column_name
|
||||||
columns.name as column_name,
|
|
||||||
case when origin = 'c' then 'regular' when origin = 'u' then 'unique' when origin = 'pk' then 'primary key' else origin end as index_type
|
|
||||||
from tables
|
from tables
|
||||||
join pragma_index_list(tables.name) as indexes
|
join pragma_index_list(tables.name) as indexes
|
||||||
join pragma_index_info(indexes.name) as columns
|
join pragma_index_info(indexes.name) as columns
|
||||||
|
|
||||||
union
|
union
|
||||||
|
|
||||||
select '[auto-generated rowid primary key index]' as index_name,
|
select table_name,
|
||||||
tables.name as table_name,
|
column_name
|
||||||
columns.name as column_name,
|
from columns
|
||||||
'primary key' as index_type
|
where column_name = 'rowid'
|
||||||
from tables
|
and is_primary_key != 0 -- `pk` is either 0, or the 1-based index of the column within the primary key
|
||||||
join pragma_table_info(tables.name) as "columns"
|
), foreign_keys as (
|
||||||
where columns.name = 'rowid'
|
select * from columns where fk_target_column is not null
|
||||||
and columns.pk != 0 -- `pk` is either 0, or the 1-based index of the column within the primary key
|
|
||||||
), foreign_key_targets as (
|
|
||||||
select tables.name as "fk_source_table",
|
|
||||||
fk."from" as "fk_source_column",
|
|
||||||
fk."table" as fk_target_table,
|
|
||||||
fk."to" as fk_target_column
|
|
||||||
from tables
|
|
||||||
join pragma_foreign_key_list(tables.name) as fk
|
|
||||||
)
|
)
|
||||||
select fk_source_table, fk_source_column, fk_target_table, fk_target_column, ifnull(index_info.table_name, 'NULL') as index_table, ifnull(index_info.column_name, 'NULL') as index_column
|
select 'Foreign keys should point to indexed columns' as error_msg,
|
||||||
from foreign_key_targets
|
foreign_keys.table_name as table_name,
|
||||||
left join index_info on foreign_key_targets.fk_target_table = index_info.table_name and foreign_key_targets.fk_target_column = index_info.column_name
|
foreign_keys.column_name as column_name
|
||||||
where index_column = 'NULL';
|
from foreign_keys
|
||||||
|
left join index_info on foreign_keys.fk_target_table = index_info.table_name
|
||||||
|
and foreign_keys.fk_target_column = index_info.column_name
|
||||||
|
where index_info.column_name is null;
|
||||||
|
|
||||||
|
|
||||||
-- ==============
|
-- ==============
|
||||||
@ -133,9 +119,6 @@ select * from (
|
|||||||
union
|
union
|
||||||
select * from lint_check__require_explicit_primary_key
|
select * from lint_check__require_explicit_primary_key
|
||||||
union
|
union
|
||||||
select 'Foreign keys should point to indexed columns' as error_msg,
|
select * from lint_check__require_indexes_for_foreign_keys
|
||||||
fk_source_table as table_name,
|
|
||||||
fk_source_column as column_name
|
|
||||||
from lint_check__require_indexes_for_foreign_keys
|
|
||||||
);
|
);
|
||||||
|
|
||||||
|
27
test.sh
Executable file
27
test.sh
Executable file
@ -0,0 +1,27 @@
|
|||||||
|
#!/bin/sh
|
||||||
|
|
||||||
|
rm data/*
|
||||||
|
for file in test_schemas/failure-*; do
|
||||||
|
echo "Testing '$file'"
|
||||||
|
test -e output.txt && rm output.txt
|
||||||
|
db_path="data/$(basename $file).db"
|
||||||
|
sqlite3 $db_path < $file
|
||||||
|
sqlite3 -column -header $db_path < lints.sql | tee output.txt
|
||||||
|
if [ ! -s output.txt ]; then
|
||||||
|
echo "Should have failed, but didn't: $file"
|
||||||
|
exit 1
|
||||||
|
fi
|
||||||
|
done
|
||||||
|
|
||||||
|
file="test_schemas/success.sql"
|
||||||
|
echo "Testing '$file'"
|
||||||
|
test -e output.txt && rm output.txt
|
||||||
|
db_path="data/$(basename $file).db"
|
||||||
|
sqlite3 $db_path < $file
|
||||||
|
sqlite3 -column -header $db_path < lints.sql | tee output.txt
|
||||||
|
if [ -s output.txt ]; then
|
||||||
|
echo "Should have passed, but didn't: $file"
|
||||||
|
exit 1
|
||||||
|
fi
|
||||||
|
|
||||||
|
echo "Tests passed!"
|
Loading…
x
Reference in New Issue
Block a user