diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..3866d7a --- /dev/null +++ b/.gitignore @@ -0,0 +1,2 @@ +data +output.txt diff --git a/lints.sql b/lints.sql index 236462a..7b6a239 100644 --- a/lints.sql +++ b/lints.sql @@ -1,6 +1,8 @@ create temporary view tables as - -- select * from sqlite_schema where type = 'table'; - select l.* from sqlite_schema s left join pragma_table_list l on s.name = l.name where s.type = 'table'; + select l.* + from sqlite_schema s + left join pragma_table_list l on s.name = l.name + where s.type = 'table'; 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 create temporary view lint_check__require_not_null as select 'Column should should be "not null"' as error_msg, - tables.name as table_name, - table_info.name as column_name - from tables - join pragma_table_info(tables.name) as table_info - where not exists ( - select 1 from pragma_foreign_key_list(tables.name) as fk - where fk."from" = table_info.name - ) - and (table_info."notnull" = 0 and table_info.pk = 0); + table_name, + column_name + from columns + where columns."notnull" = 0 + and fk_target_column is null + and is_primary_key = 0; -- primary keys are automatically not-null, but aren't listed as such in pragma_table_info -- Require all non-foreign-key, non-primary-key fields to have a default value create temporary view lint_check__require_default_values as select 'Column should have a default value' as error_msg, - tables.name as table_name, - table_info.name as column_name - from tables - join pragma_table_info(tables.name) as table_info - where table_info.pk = 0 - and not exists ( - select 1 from pragma_foreign_key_list(tables.name) as fk - where fk."from" = table_info.name - ) - and table_info.dflt_value is null; + table_name, + column_name + from columns + where table_info.dflt_value is null + and fk_target_column is null + and is_primary_key = 0; -- 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, '' as column_name from tables - where strict = 0 - and name not in ('sqlite_schema', 'sqlite_temp_schema'); + where strict = 0; -- Forbid use 'int' column types create temporary view lint_check__forbid_int_type as select 'Column should use "integer" type instead of "int"' as error_msg, - tables.name as table_name, - table_info.name as column_name - from tables - join pragma_table_info(tables.name) as table_info - where table_info.type like 'int'; + table_name, + column_name + from columns + where column_type like 'int'; -- 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, '' as column_name 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 create temporary view lint_check__require_indexes_for_foreign_keys as with index_info as ( - select indexes.name as index_name, - tables.name as table_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 + select tables.name as table_name, + columns.name as column_name from tables join pragma_index_list(tables.name) as indexes join pragma_index_info(indexes.name) as columns union - select '[auto-generated rowid primary key index]' as index_name, - tables.name as table_name, - columns.name as column_name, - 'primary key' as index_type - from tables - join pragma_table_info(tables.name) as "columns" - where columns.name = 'rowid' - 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 table_name, + column_name + from columns + where column_name = 'rowid' + and is_primary_key != 0 -- `pk` is either 0, or the 1-based index of the column within the primary key + ), foreign_keys as ( + select * from columns where fk_target_column is not null ) -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 - from foreign_key_targets - 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 - where index_column = 'NULL'; +select 'Foreign keys should point to indexed columns' as error_msg, + foreign_keys.table_name as table_name, + foreign_keys.column_name as column_name + 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 select * from lint_check__require_explicit_primary_key union - select 'Foreign keys should point to indexed columns' as error_msg, - fk_source_table as table_name, - fk_source_column as column_name - from lint_check__require_indexes_for_foreign_keys + select * from lint_check__require_indexes_for_foreign_keys ); diff --git a/test.sh b/test.sh new file mode 100755 index 0000000..857cbbf --- /dev/null +++ b/test.sh @@ -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!" diff --git a/test_schemas/total-failure.sql b/test_schemas/failure-total.sql similarity index 100% rename from test_schemas/total-failure.sql rename to test_schemas/failure-total.sql