From 59d1c1d6f387d248ebdd03a79e9034ca97141d4f Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 19:43:31 +0100 Subject: [PATCH 01/17] chore(splinter): initial commit --- .github/workflows/pull_request.yml | 2 + Cargo.lock | 14 + Cargo.toml | 1 + .../src/categories.rs | 30 +- ...d5a53712d68afd273423f9310cd793586f532.json | 74 ++ crates/pgls_splinter/Cargo.toml | 28 + crates/pgls_splinter/TODO.md | 1 + crates/pgls_splinter/build.rs | 109 ++ crates/pgls_splinter/src/convert.rs | 101 ++ crates/pgls_splinter/src/diagnostics.rs | 81 ++ crates/pgls_splinter/src/lib.rs | 48 + crates/pgls_splinter/src/query.rs | 57 + crates/pgls_splinter/tests/diagnostics.rs | 267 ++++ .../tests/snapshots/multiple_issues.snap | 23 + .../tests/snapshots/no_issues.snap | 6 + .../tests/snapshots/no_primary_key.snap | 12 + .../snapshots/policy_exists_rls_disabled.snap | 12 + .../snapshots/rls_disabled_in_public.snap | 6 + .../snapshots/unindexed_foreign_key.snap | 13 + crates/pgls_splinter/vendor/COMMIT_SHA.txt | 1 + crates/pgls_splinter/vendor/splinter.sql | 1149 +++++++++++++++++ justfile | 2 + xtask/codegen/src/generate_splinter.rs | 166 +++ xtask/codegen/src/lib.rs | 5 + xtask/codegen/src/main.rs | 5 +- 25 files changed, 2211 insertions(+), 2 deletions(-) create mode 100644 crates/pgls_splinter/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json create mode 100644 crates/pgls_splinter/Cargo.toml create mode 100644 crates/pgls_splinter/TODO.md create mode 100644 crates/pgls_splinter/build.rs create mode 100644 crates/pgls_splinter/src/convert.rs create mode 100644 crates/pgls_splinter/src/diagnostics.rs create mode 100644 crates/pgls_splinter/src/lib.rs create mode 100644 crates/pgls_splinter/src/query.rs create mode 100644 crates/pgls_splinter/tests/diagnostics.rs create mode 100644 crates/pgls_splinter/tests/snapshots/multiple_issues.snap create mode 100644 crates/pgls_splinter/tests/snapshots/no_issues.snap create mode 100644 crates/pgls_splinter/tests/snapshots/no_primary_key.snap create mode 100644 crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap create mode 100644 crates/pgls_splinter/tests/snapshots/rls_disabled_in_public.snap create mode 100644 crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap create mode 100644 crates/pgls_splinter/vendor/COMMIT_SHA.txt create mode 100644 crates/pgls_splinter/vendor/splinter.sql create mode 100644 xtask/codegen/src/generate_splinter.rs diff --git a/.github/workflows/pull_request.yml b/.github/workflows/pull_request.yml index eeadc9669..3a979a34d 100644 --- a/.github/workflows/pull_request.yml +++ b/.github/workflows/pull_request.yml @@ -272,6 +272,8 @@ jobs: run: cargo run -p xtask_codegen -- configuration - name: Run the bindings codegen run: cargo run -p xtask_codegen -- bindings + - name: Run the splinter codegen + run: cargo run -p xtask_codegen -- splinter - name: Run the docs codegen run: cargo run -p docs_codegen - name: Check for git diff -- run "just ready" if you see an error diff --git a/Cargo.lock b/Cargo.lock index ae60d7d1d..9a9688a34 100644 --- a/Cargo.lock +++ b/Cargo.lock @@ -2987,6 +2987,20 @@ dependencies = [ "tokio", ] +[[package]] +name = "pgls_splinter" +version = "0.0.0" +dependencies = [ + "insta", + "pgls_console", + "pgls_diagnostics", + "pgls_test_utils", + "serde", + "serde_json", + "sqlx", + "ureq", +] + [[package]] name = "pgls_statement_splitter" version = "0.0.0" diff --git a/Cargo.toml b/Cargo.toml index fd9455a8d..9b09e8ea4 100644 --- a/Cargo.toml +++ b/Cargo.toml @@ -82,6 +82,7 @@ pgls_query = { path = "./crates/pgls_query", version = "0.0.0" pgls_query_ext = { path = "./crates/pgls_query_ext", version = "0.0.0" } pgls_query_macros = { path = "./crates/pgls_query_macros", version = "0.0.0" } pgls_schema_cache = { path = "./crates/pgls_schema_cache", version = "0.0.0" } +pgls_splinter = { path = "./crates/pgls_splinter", version = "0.0.0" } pgls_statement_splitter = { path = "./crates/pgls_statement_splitter", version = "0.0.0" } pgls_suppressions = { path = "./crates/pgls_suppressions", version = "0.0.0" } pgls_text_edit = { path = "./crates/pgls_text_edit", version = "0.0.0" } diff --git a/crates/pgls_diagnostics_categories/src/categories.rs b/crates/pgls_diagnostics_categories/src/categories.rs index 53282780c..78619c8e8 100644 --- a/crates/pgls_diagnostics_categories/src/categories.rs +++ b/crates/pgls_diagnostics_categories/src/categories.rs @@ -47,6 +47,30 @@ define_categories! { "lint/safety/runningStatementWhileHoldingAccessExclusive": "https://pg-language-server.com/latest/rules/running-statement-while-holding-access-exclusive", "lint/safety/transactionNesting": "https://pg-language-server.com/latest/rules/transaction-nesting", // end lint rules + // splinter rules start + "dblint/splinter/authRlsInitplan": "https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan", + "dblint/splinter/authUsersExposed": "https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed", + "dblint/splinter/duplicateIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index", + "dblint/splinter/extensionInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public", + "dblint/splinter/extensionVersionsOutdated": "https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated", + "dblint/splinter/fkeyToAuthUnique": "https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique", + "dblint/splinter/foreignTableInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api", + "dblint/splinter/functionSearchPathMutable": "https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable", + "dblint/splinter/insecureQueueExposedInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api", + "dblint/splinter/materializedViewInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api", + "dblint/splinter/multiplePermissivePolicies": "https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies", + "dblint/splinter/noPrimaryKey": "https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key", + "dblint/splinter/policyExistsRlsDisabled": "https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled", + "dblint/splinter/rlsDisabledInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public", + "dblint/splinter/rlsEnabledNoPolicy": "https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy", + "dblint/splinter/rlsReferencesUserMetadata": "https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata", + "dblint/splinter/securityDefinerView": "https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view", + "dblint/splinter/tableBloat": "https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat", + "dblint/splinter/unindexedForeignKeys": "https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys", + "dblint/splinter/unknown": "https://pg-language-server.com/latest", + "dblint/splinter/unsupportedRegTypes": "https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types", + "dblint/splinter/unusedIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index", + // splinter rules end ; // General categories "stdin", @@ -68,5 +92,9 @@ define_categories! { "lint", "lint/performance", "lint/safety", + // splinter groups start + "dblint", + "dblint/splinter", + // splinter groups end // Lint groups end -} +} \ No newline at end of file diff --git a/crates/pgls_splinter/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json b/crates/pgls_splinter/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json new file mode 100644 index 000000000..c460f458d --- /dev/null +++ b/crates/pgls_splinter/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json @@ -0,0 +1,74 @@ +{ + "db_name": "PostgreSQL", + "query": "\n(\nwith foreign_keys as (\n select\n cl.relnamespace::regnamespace::text as schema_name,\n cl.relname as table_name,\n cl.oid as table_oid,\n ct.conname as fkey_name,\n ct.conkey as col_attnums\n from\n pg_catalog.pg_constraint ct\n join pg_catalog.pg_class cl -- fkey owning table\n on ct.conrelid = cl.oid\n left join pg_catalog.pg_depend d\n on d.objid = cl.oid\n and d.deptype = 'e'\n where\n ct.contype = 'f' -- foreign key constraints\n and d.objid is null -- exclude tables that are dependencies of extensions\n and cl.relnamespace::regnamespace::text not in (\n 'pg_catalog', 'information_schema', 'auth', 'storage', 'vault', 'extensions'\n )\n),\nindex_ as (\n select\n pi.indrelid as table_oid,\n indexrelid::regclass as index_,\n string_to_array(indkey::text, ' ')::smallint[] as col_attnums\n from\n pg_catalog.pg_index pi\n where\n indisvalid\n)\nselect\n 'unindexed_foreign_keys' as \"name!\",\n 'Unindexed foreign keys' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Identifies foreign key constraints without a covering index, which can impact database performance.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a foreign key \\`%s\\` without a covering index. This can lead to suboptimal query performance.',\n fk.schema_name,\n fk.table_name,\n fk.fkey_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys' as \"remediation!\",\n jsonb_build_object(\n 'schema', fk.schema_name,\n 'name', fk.table_name,\n 'type', 'table',\n 'fkey_name', fk.fkey_name,\n 'fkey_columns', fk.col_attnums\n ) as \"metadata!\",\n format('unindexed_foreign_keys_%s_%s_%s', fk.schema_name, fk.table_name, fk.fkey_name) as \"cache_key!\"\nfrom\n foreign_keys fk\n left join index_ idx\n on fk.table_oid = idx.table_oid\n and fk.col_attnums = idx.col_attnums[1:array_length(fk.col_attnums, 1)]\n left join pg_catalog.pg_depend dep\n on idx.table_oid = dep.objid\n and dep.deptype = 'e'\nwhere\n idx.index_ is null\n and fk.schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\norder by\n fk.schema_name,\n fk.table_name,\n fk.fkey_name)\nunion all\n(\nselect\n 'auth_users_exposed' as \"name!\",\n 'Exposed Auth Users' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects if auth.users is exposed to anon or authenticated roles via a view or materialized view in schemas exposed to PostgREST, potentially compromising user data security.' as \"description!\",\n format(\n 'View/Materialized View \"%s\" in the public schema may expose \\`auth.users\\` data to anon or authenticated roles.',\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view',\n 'exposed_to', array_remove(array_agg(DISTINCT case when pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') then 'anon' when pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') then 'authenticated' end), null)\n ) as \"metadata!\",\n format('auth_users_exposed_%s_%s', n.nspname, c.relname) as \"cache_key!\"\nfrom\n -- Identify the oid for auth.users\n pg_catalog.pg_class auth_users_pg_class\n join pg_catalog.pg_namespace auth_users_pg_namespace\n on auth_users_pg_class.relnamespace = auth_users_pg_namespace.oid\n and auth_users_pg_class.relname = 'users'\n and auth_users_pg_namespace.nspname = 'auth'\n -- Depends on auth.users\n join pg_catalog.pg_depend d\n on d.refobjid = auth_users_pg_class.oid\n join pg_catalog.pg_rewrite r\n on r.oid = d.objid\n join pg_catalog.pg_class c\n on c.oid = r.ev_class\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n join pg_catalog.pg_class pg_class_auth_users\n on d.refobjid = pg_class_auth_users.oid\nwhere\n d.deptype = 'n'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n -- Exclude self\n and c.relname <> '0002_auth_users_exposed'\n -- There are 3 insecure configurations\n and\n (\n -- Materialized views don't support RLS so this is insecure by default\n (c.relkind in ('m')) -- m for materialized view\n or\n -- Standard View, accessible to anon or authenticated that is security_definer\n (\n c.relkind = 'v' -- v for view\n -- Exclude security invoker views\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n )\n or\n -- Standard View, security invoker, but no RLS enabled on auth.users\n (\n c.relkind in ('v') -- v for view\n -- is security invoker\n and (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n and not pg_class_auth_users.relrowsecurity\n )\n )\ngroup by\n n.nspname,\n c.relname,\n c.oid)\nunion all\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n pc.relrowsecurity as is_rls_active,\n polname as policy_name,\n polpermissive as is_permissive, -- if not, then restrictive\n (select array_agg(r::regrole) from unnest(polroles) as x(r)) as roles,\n case polcmd\n when 'r' then 'SELECT'\n when 'a' then 'INSERT'\n when 'w' then 'UPDATE'\n when 'd' then 'DELETE'\n when '*' then 'ALL'\n end as command,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'auth_rls_initplan' as \"name!\",\n 'Auth RLS Initialization Plan' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if calls to \\`current_setting()\\` and \\`auth.()\\` in RLS policies are being unnecessarily re-evaluated for each row' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that re-evaluates current_setting() or auth.() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \\`auth.()\\` with \\`(select auth.())\\`. See [docs](https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select) for more info.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('auth_rls_init_plan_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n is_rls_active\n -- NOTE: does not include realtime in support of monitoring policies on realtime.messages\n and schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.uid()\n (\n qual like '%auth.uid()%'\n and lower(qual) not like '%select auth.uid()%'\n )\n or (\n qual like '%auth.jwt()%'\n and lower(qual) not like '%select auth.jwt()%'\n )\n or (\n qual like '%auth.role()%'\n and lower(qual) not like '%select auth.role()%'\n )\n or (\n qual like '%auth.email()%'\n and lower(qual) not like '%select auth.email()%'\n )\n or (\n qual like '%current\\_setting(%)%'\n and lower(qual) not like '%select current\\_setting(%)%'\n )\n or (\n with_check like '%auth.uid()%'\n and lower(with_check) not like '%select auth.uid()%'\n )\n or (\n with_check like '%auth.jwt()%'\n and lower(with_check) not like '%select auth.jwt()%'\n )\n or (\n with_check like '%auth.role()%'\n and lower(with_check) not like '%select auth.role()%'\n )\n or (\n with_check like '%auth.email()%'\n and lower(with_check) not like '%select auth.email()%'\n )\n or (\n with_check like '%current\\_setting(%)%'\n and lower(with_check) not like '%select current\\_setting(%)%'\n )\n ))\nunion all\n(\nselect\n 'no_primary_key' as \"name!\",\n 'No Primary Key' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` does not have a primary key',\n pgns.nspname,\n pgc.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key' as \"remediation!\",\n jsonb_build_object(\n 'schema', pgns.nspname,\n 'name', pgc.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'no_primary_key_%s_%s',\n pgns.nspname,\n pgc.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class pgc\n join pg_catalog.pg_namespace pgns\n on pgns.oid = pgc.relnamespace\n left join pg_catalog.pg_index pgi\n on pgi.indrelid = pgc.oid\n left join pg_catalog.pg_depend dep\n on pgc.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n pgc.relkind = 'r' -- regular tables\n and pgns.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n pgc.oid,\n pgns.nspname,\n pgc.relname\nhaving\n max(coalesce(pgi.indisprimary, false)::int) = 0)\nunion all\n(\nselect\n 'unused_index' as \"name!\",\n 'Unused Index' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if an index has never been used and may be a candidate for removal.' as \"description!\",\n format(\n 'Index \\`%s\\` on table \\`%s.%s\\` has not been used',\n psui.indexrelname,\n psui.schemaname,\n psui.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', psui.schemaname,\n 'name', psui.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unused_index_%s_%s_%s',\n psui.schemaname,\n psui.relname,\n psui.indexrelname\n ) as \"cache_key!\"\n\nfrom\n pg_catalog.pg_stat_user_indexes psui\n join pg_catalog.pg_index pi\n on psui.indexrelid = pi.indexrelid\n left join pg_catalog.pg_depend dep\n on psui.relid = dep.objid\n and dep.deptype = 'e'\nwhere\n psui.idx_scan = 0\n and not pi.indisunique\n and not pi.indisprimary\n and dep.objid is null -- exclude tables owned by extensions\n and psui.schemaname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n(\nselect\n 'multiple_permissive_policies' as \"name!\",\n 'Multiple Permissive Policies' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if multiple permissive row level security policies are present on a table for the same \\`role\\` and \\`action\\` (e.g. insert). Multiple permissive policies are suboptimal for performance as each policy must be executed for every relevant query.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has multiple permissive policies for role \\`%s\\` for action \\`%s\\`. Policies include \\`%s\\`',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'multiple_permissive_policies_%s_%s_%s_%s',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_roles r\n on p.polroles @> array[r.oid]\n or p.polroles = array[0::oid]\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e',\n lateral (\n select x.cmd\n from unnest((\n select\n case p.polcmd\n when 'r' then array['SELECT']\n when 'a' then array['INSERT']\n when 'w' then array['UPDATE']\n when 'd' then array['DELETE']\n when '*' then array['SELECT', 'INSERT', 'UPDATE', 'DELETE']\n else array['ERROR']\n end as actions\n )) x(cmd)\n ) act(cmd)\nwhere\n c.relkind = 'r' -- regular tables\n and p.polpermissive -- policy is permissive\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and r.rolname not like 'pg_%'\n and r.rolname not like 'supabase%admin'\n and not r.rolbypassrls\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\nhaving\n count(1) > 1)\nunion all\n(\nselect\n 'policy_exists_rls_disabled' as \"name!\",\n 'Policy Exists RLS Disabled' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) policies have been created, but RLS has not been enabled for the underlying table.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS policies but RLS is not enabled on the table. Policies include %s.',\n n.nspname,\n c.relname,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'policy_exists_rls_disabled_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is disabled\n and not c.relrowsecurity\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n(\nselect\n 'rls_enabled_no_policy' as \"name!\",\n 'RLS Enabled No Policy' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has been enabled on a table but no RLS policies have been created.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS enabled, but no policies exist',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_enabled_no_policy_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n left join pg_catalog.pg_policy p\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is enabled\n and c.relrowsecurity\n and p.polname is null\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n(\nselect\n 'duplicate_index' as \"name!\",\n 'Duplicate Index' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects cases where two ore more identical indexes exist.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has identical indexes %s. Drop all except one of them',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', case\n when c.relkind = 'r' then 'table'\n when c.relkind = 'm' then 'materialized view'\n else 'ERROR'\n end,\n 'indexes', array_agg(pi.indexname order by pi.indexname)\n ) as \"metadata!\",\n format(\n 'duplicate_index_%s_%s_%s',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_indexes pi\n join pg_catalog.pg_namespace n\n on n.nspname = pi.schemaname\n join pg_catalog.pg_class c\n on pi.tablename = c.relname\n and n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind in ('r', 'm') -- tables and materialized views\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relkind,\n c.relname,\n replace(pi.indexdef, pi.indexname, '')\nhaving\n count(*) > 1)\nunion all\n(\nselect\n 'security_definer_view' as \"name!\",\n 'Security Definer View' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects views defined with the SECURITY DEFINER property. These views enforce Postgres permissions and row level security policies (RLS) of the view creator, rather than that of the querying user' as \"description!\",\n format(\n 'View \\`%s.%s\\` is defined with the SECURITY DEFINER property',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view'\n ) as \"metadata!\",\n format(\n 'security_definer_view_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'v'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and substring(pg_catalog.version() from 'PostgreSQL ([0-9]+)') >= '15' -- security invoker was added in pg15\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude views owned by extensions\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n ))\nunion all\n(\nselect\n 'function_search_path_mutable' as \"name!\",\n 'Function Search Path Mutable' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects functions where the search_path parameter is not set.' as \"description!\",\n format(\n 'Function \\`%s.%s\\` has a role mutable search_path',\n n.nspname,\n p.proname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', p.proname,\n 'type', 'function'\n ) as \"metadata!\",\n format(\n 'function_search_path_mutable_%s_%s_%s',\n n.nspname,\n p.proname,\n md5(p.prosrc) -- required when function is polymorphic\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_proc p\n join pg_catalog.pg_namespace n\n on p.pronamespace = n.oid\n left join pg_catalog.pg_depend dep\n on p.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude functions owned by extensions\n -- Search path not set\n and not exists (\n select 1\n from unnest(coalesce(p.proconfig, '{}')) as config\n where config like 'search_path=%'\n ))\nunion all\n(\nselect\n 'rls_disabled_in_public' as \"name!\",\n 'RLS Disabled in Public' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has not been enabled on tables in schemas exposed to PostgREST' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind = 'r' -- regular tables\n -- RLS is disabled\n and not c.relrowsecurity\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n(\nselect\n 'extension_in_public' as \"name!\",\n 'Extension in Public' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions installed in the \\`public\\` schema.' as \"description!\",\n format(\n 'Extension \\`%s\\` is installed in the public schema. Move it to another schema.',\n pe.extname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', pe.extnamespace::regnamespace,\n 'name', pe.extname,\n 'type', 'extension'\n ) as \"metadata!\",\n format(\n 'extension_in_public_%s',\n pe.extname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_extension pe\nwhere\n -- plpgsql is installed by default in public and outside user control\n -- confirmed safe\n pe.extname not in ('plpgsql')\n -- Scoping this to public is not optimal. Ideally we would use the postgres\n -- search path. That currently isn't available via SQL. In other lints\n -- we have used has_schema_privilege('anon', 'extensions', 'USAGE') but that\n -- is not appropriate here as it would evaluate true for the extensions schema\n and pe.extnamespace::regnamespace::text = 'public')\nunion all\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n polname as policy_name,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'rls_references_user_metadata' as \"name!\",\n 'RLS references user metadata' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects when Supabase Auth user_metadata is referenced insecurely in a row level security (RLS) policy.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that references Supabase Auth \\`user_metadata\\`. \\`user_metadata\\` is editable by end users and should never be used in a security context.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('rls_references_user_metadata_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.jwt() -> 'user_metadata'\n -- False positives are possible, but it isn't practical to string match\n -- If false positive rate is too high, this expression can iterate\n qual like '%auth.jwt()%user_metadata%'\n or qual like '%current_setting(%request.jwt.claims%)%user_metadata%'\n or with_check like '%auth.jwt()%user_metadata%'\n or with_check like '%current_setting(%request.jwt.claims%)%user_metadata%'\n ))\nunion all\n(\nselect\n 'materialized_view_in_api' as \"name!\",\n 'Materialized View in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects materialized views that are accessible over the Data APIs.' as \"description!\",\n format(\n 'Materialized view \\`%s.%s\\` is selectable by anon or authenticated roles',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'materialized view'\n ) as \"metadata!\",\n format(\n 'materialized_view_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'm'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n(\nselect\n 'foreign_table_in_api' as \"name!\",\n 'Foreign Table in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects foreign tables that are accessible over APIs. Foreign tables do not respect row level security policies.' as \"description!\",\n format(\n 'Foreign table \\`%s.%s\\` is accessible over APIs',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'foreign table'\n ) as \"metadata!\",\n format(\n 'foreign_table_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'f'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n(\nselect\n 'unsupported_reg_types' as \"name!\",\n 'Unsupported reg types' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Identifies columns using unsupported reg* types outside pg_catalog schema, which prevents database upgrades using pg_upgrade.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a column \\`%s\\` with unsupported reg* type \\`%s\\`.',\n n.nspname,\n c.relname,\n a.attname,\n t.typname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'column', a.attname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unsupported_reg_types_%s_%s_%s',\n n.nspname,\n c.relname,\n a.attname\n ) AS cache_key\nfrom\n pg_catalog.pg_attribute a\n join pg_catalog.pg_class c\n on a.attrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_type t\n on a.atttypid = t.oid\n join pg_catalog.pg_namespace tn\n on t.typnamespace = tn.oid\nwhere\n tn.nspname = 'pg_catalog'\n and t.typname in ('regcollation', 'regconfig', 'regdictionary', 'regnamespace', 'regoper', 'regoperator', 'regproc', 'regprocedure')\n and n.nspname not in ('pg_catalog', 'information_schema', 'pgsodium'))\nunion all\n(\nselect\n 'insecure_queue_exposed_in_api' as \"name!\",\n 'Insecure Queue Exposed in API' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where an insecure Queue is exposed over Data APIs' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind in ('r', 'I') -- regular or partitioned tables\n and not c.relrowsecurity -- RLS is disabled\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = 'pgmq' -- tables in the pgmq schema\n and c.relname like 'q_%' -- only queue tables\n -- Constant requirements\n and 'pgmq_public' = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))))\nunion all\n(\nwith constants as (\n select current_setting('block_size')::numeric as bs, 23 as hdr, 4 as ma\n),\n\nbloat_info as (\n select\n ma,\n bs,\n schemaname,\n tablename,\n (datawidth + (hdr + ma - (case when hdr % ma = 0 then ma else hdr % ma end)))::numeric as datahdr,\n (maxfracsum * (nullhdr + ma - (case when nullhdr % ma = 0 then ma else nullhdr % ma end))) as nullhdr2\n from (\n select\n schemaname,\n tablename,\n hdr,\n ma,\n bs,\n sum((1 - null_frac) * avg_width) as datawidth,\n max(null_frac) as maxfracsum,\n hdr + (\n select 1 + count(*) / 8\n from pg_stats s2\n where\n null_frac <> 0\n and s2.schemaname = s.schemaname\n and s2.tablename = s.tablename\n ) as nullhdr\n from pg_stats s, constants\n group by 1, 2, 3, 4, 5\n ) as foo\n),\n\ntable_bloat as (\n select\n schemaname,\n tablename,\n cc.relpages,\n bs,\n ceil((cc.reltuples * ((datahdr + ma -\n (case when datahdr % ma = 0 then ma else datahdr % ma end)) + nullhdr2 + 4)) / (bs - 20::float)) as otta\n from\n bloat_info\n join pg_class cc\n on cc.relname = bloat_info.tablename\n join pg_namespace nn\n on cc.relnamespace = nn.oid\n and nn.nspname = bloat_info.schemaname\n and nn.nspname <> 'information_schema'\n where\n cc.relkind = 'r'\n and cc.relam = (select oid from pg_am where amname = 'heap')\n),\n\nbloat_data as (\n select\n 'table' as type,\n schemaname,\n tablename as object_name,\n round(case when otta = 0 then 0.0 else table_bloat.relpages / otta::numeric end, 1) as bloat,\n case when relpages < otta then 0 else (bs * (table_bloat.relpages - otta)::bigint)::bigint end as raw_waste\n from\n table_bloat\n)\n\nselect\n 'table_bloat' as \"name!\",\n 'Table Bloat' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table has excess bloat and may benefit from maintenance operations like vacuum full or cluster.' as \"description!\",\n format(\n 'Table `%s`.`%s` has excessive bloat',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat' as \"remediation!\",\n jsonb_build_object(\n 'schema', bloat_data.schemaname,\n 'name', bloat_data.object_name,\n 'type', bloat_data.type\n ) as \"metadata!\",\n format(\n 'table_bloat_%s_%s',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"cache_key!\"\nfrom\n bloat_data\nwhere\n bloat > 70.0\n and raw_waste > (20 * 1024 * 1024) -- filter for waste > 200 MB\norder by\n schemaname,\n object_name)\nunion all\n(\nselect\n 'fkey_to_auth_unique' as \"name!\",\n 'Foreign Key to Auth Unique Constraint' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects user defined foreign keys to unique constraints in the auth schema.' as \"description!\",\n format(\n 'Table `%s`.`%s` has a foreign key `%s` referencing an auth unique constraint',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname -- fkey name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c_rel.relname,\n 'foreign_key', c.conname\n ) as \"metadata!\",\n format(\n 'fkey_to_auth_unique_%s_%s_%s',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_constraint c\n join pg_catalog.pg_class c_rel\n on c.conrelid = c_rel.oid\n join pg_catalog.pg_namespace n\n on c_rel.relnamespace = n.oid\n join pg_catalog.pg_class ref_rel\n on c.confrelid = ref_rel.oid\n join pg_catalog.pg_namespace cn\n on ref_rel.relnamespace = cn.oid\n join pg_catalog.pg_index i\n on c.conindid = i.indexrelid\nwhere c.contype = 'f'\n and cn.nspname = 'auth'\n and i.indisunique\n and not i.indisprimary)\nunion all\n(\nselect\n 'extension_versions_outdated' as \"name!\",\n 'Extension Versions Outdated' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions that are not using the default (recommended) version.' as \"description!\",\n format(\n 'Extension `%s` is using version `%s` but version `%s` is available. Using outdated extension versions may expose the database to security vulnerabilities.',\n ext.name,\n ext.installed_version,\n ext.default_version\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated' as \"remediation!\",\n jsonb_build_object(\n 'extension_name', ext.name,\n 'installed_version', ext.installed_version,\n 'default_version', ext.default_version\n ) as \"metadata!\",\n format(\n 'extension_versions_outdated_%s_%s',\n ext.name,\n ext.installed_version\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_available_extensions ext\njoin\n -- ignore versions not in pg_available_extension_versions\n -- e.g. residue of pg_upgrade\n pg_catalog.pg_available_extension_versions extv\n on extv.name = ext.name and extv.installed\nwhere\n ext.installed_version is not null\n and ext.default_version is not null\n and ext.installed_version != ext.default_version\norder by\n ext.name)", + "describe": { + "columns": [ + { + "ordinal": 0, + "name": "name!", + "type_info": "Text" + }, + { + "ordinal": 1, + "name": "title!", + "type_info": "Text" + }, + { + "ordinal": 2, + "name": "level!", + "type_info": "Text" + }, + { + "ordinal": 3, + "name": "facing!", + "type_info": "Text" + }, + { + "ordinal": 4, + "name": "categories!", + "type_info": "TextArray" + }, + { + "ordinal": 5, + "name": "description!", + "type_info": "Text" + }, + { + "ordinal": 6, + "name": "detail!", + "type_info": "Text" + }, + { + "ordinal": 7, + "name": "remediation!", + "type_info": "Text" + }, + { + "ordinal": 8, + "name": "metadata!", + "type_info": "Jsonb" + }, + { + "ordinal": 9, + "name": "cache_key!", + "type_info": "Text" + } + ], + "parameters": { + "Left": [] + }, + "nullable": [ + null, + null, + null, + null, + null, + null, + null, + null, + null, + null + ] + }, + "hash": "b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532" +} diff --git a/crates/pgls_splinter/Cargo.toml b/crates/pgls_splinter/Cargo.toml new file mode 100644 index 000000000..f07273e2a --- /dev/null +++ b/crates/pgls_splinter/Cargo.toml @@ -0,0 +1,28 @@ +[package] +authors.workspace = true +categories.workspace = true +description = "" +edition.workspace = true +homepage.workspace = true +keywords.workspace = true +license.workspace = true +name = "pgls_splinter" +repository.workspace = true +version = "0.0.0" + +[dependencies] +pgls_diagnostics.workspace = true +serde.workspace = true +serde_json.workspace = true +sqlx.workspace = true + +[build-dependencies] +ureq = "2.10" + +[dev-dependencies] +insta.workspace = true +pgls_console.workspace = true +pgls_test_utils.workspace = true + +[lib] +doctest = false diff --git a/crates/pgls_splinter/TODO.md b/crates/pgls_splinter/TODO.md new file mode 100644 index 000000000..25f48ac22 --- /dev/null +++ b/crates/pgls_splinter/TODO.md @@ -0,0 +1 @@ +- implement ignore / include and config. try to refactor existing analyser infrastructure to be re-used. diff --git a/crates/pgls_splinter/build.rs b/crates/pgls_splinter/build.rs new file mode 100644 index 000000000..fc12a7305 --- /dev/null +++ b/crates/pgls_splinter/build.rs @@ -0,0 +1,109 @@ +use std::env; +use std::fs; +use std::path::Path; + +// Update this commit SHA to pull in a new version of splinter.sql +const SPLINTER_COMMIT_SHA: &str = "27ea2ece65464213e466cd969cc61b6940d16219"; + +fn main() { + let out_dir = env::var("CARGO_MANIFEST_DIR").unwrap(); + let vendor_dir = Path::new(&out_dir).join("vendor"); + let sql_file = vendor_dir.join("splinter.sql"); + let sha_file = vendor_dir.join("COMMIT_SHA.txt"); + + // Create vendor directory if it doesn't exist + if !vendor_dir.exists() { + fs::create_dir_all(&vendor_dir).expect("Failed to create vendor directory"); + } + + // Check if we need to download + let needs_download = if !sql_file.exists() || !sha_file.exists() { + true + } else { + // Check if stored SHA matches current constant + let stored_sha = fs::read_to_string(&sha_file) + .expect("Failed to read COMMIT_SHA.txt") + .trim() + .to_string(); + stored_sha != SPLINTER_COMMIT_SHA + }; + + if needs_download { + println!( + "cargo:warning=Downloading splinter.sql from GitHub (commit: {SPLINTER_COMMIT_SHA})" + ); + download_and_process_sql(&sql_file); + fs::write(&sha_file, SPLINTER_COMMIT_SHA).expect("Failed to write COMMIT_SHA.txt"); + } + + // Tell cargo to rerun if build.rs or SHA file changes + println!("cargo:rerun-if-changed=build.rs"); + println!("cargo:rerun-if-changed=vendor/COMMIT_SHA.txt"); +} + +fn download_and_process_sql(dest_path: &Path) { + let url = format!( + "https://raw.githubusercontent.com/supabase/splinter/{SPLINTER_COMMIT_SHA}/splinter.sql" + ); + + // Download the file + let response = ureq::get(&url) + .call() + .expect("Failed to download splinter.sql"); + + let content = response + .into_string() + .expect("Failed to read response body"); + + // Remove the SET LOCAL search_path section + let mut processed_content = remove_set_search_path(&content); + + // Add "!" suffix to column aliases for sqlx non-null checking + processed_content = add_not_null_markers(&processed_content); + + // Write to destination + fs::write(dest_path, processed_content).expect("Failed to write splinter.sql"); + + println!("cargo:warning=Successfully downloaded and processed splinter.sql"); +} + +fn remove_set_search_path(content: &str) -> String { + content + .lines() + .filter(|line| { + let trimmed = line.trim(); + !trimmed.to_lowercase().starts_with("set local search_path") + }) + .collect::>() + .join("\n") +} + +fn add_not_null_markers(content: &str) -> String { + // Add "!" suffix to all column aliases to mark them as non-null for sqlx + // This transforms patterns like: 'value' as name + // Into: 'value' as "name!" + + let columns_to_mark = [ + "name", + "title", + "level", + "facing", + "categories", + "description", + "detail", + "remediation", + "metadata", + "cache_key", + ]; + + let mut result = content.to_string(); + + for column in &columns_to_mark { + // Match patterns like: as name, as name) + let pattern_comma = format!(" as {column}"); + let replacement_comma = format!(" as \"{column}!\""); + result = result.replace(&pattern_comma, &replacement_comma); + } + + result +} diff --git a/crates/pgls_splinter/src/convert.rs b/crates/pgls_splinter/src/convert.rs new file mode 100644 index 000000000..a9d53cfdf --- /dev/null +++ b/crates/pgls_splinter/src/convert.rs @@ -0,0 +1,101 @@ +use pgls_diagnostics::{Category, Severity, category}; +use serde_json::Value; + +use crate::{SplinterAdvices, SplinterDiagnostic, SplinterQueryResult}; + +impl From for SplinterDiagnostic { + fn from(result: SplinterQueryResult) -> Self { + let severity = parse_severity(&result.level); + + // Extract common fields from metadata + let (schema, object_name, object_type, additional_metadata) = + extract_metadata_fields(&result.metadata); + + SplinterDiagnostic { + category: rule_name_to_category(&result.name), + message: result.detail.into(), + severity, + advices: SplinterAdvices { + description: result.description, + schema, + object_name, + object_type, + remediation_url: result.remediation, + additional_metadata, + }, + } + } +} + +/// Parse severity level from the query result +fn parse_severity(level: &str) -> Severity { + match level { + "INFO" => Severity::Information, + "WARN" => Severity::Warning, + "ERROR" => Severity::Error, + _ => Severity::Information, // default to info + } +} + +/// Convert rule name to a Category +/// Note: Rule names use snake_case, but categories use camelCase +fn rule_name_to_category(name: &str) -> &'static Category { + match name { + "unindexed_foreign_keys" => category!("dblint/splinter/unindexedForeignKeys"), + "auth_users_exposed" => category!("dblint/splinter/authUsersExposed"), + "auth_rls_initplan" => category!("dblint/splinter/authRlsInitplan"), + "no_primary_key" => category!("dblint/splinter/noPrimaryKey"), + "unused_index" => category!("dblint/splinter/unusedIndex"), + "multiple_permissive_policies" => category!("dblint/splinter/multiplePermissivePolicies"), + "policy_exists_rls_disabled" => category!("dblint/splinter/policyExistsRlsDisabled"), + "rls_enabled_no_policy" => category!("dblint/splinter/rlsEnabledNoPolicy"), + "duplicate_index" => category!("dblint/splinter/duplicateIndex"), + "security_definer_view" => category!("dblint/splinter/securityDefinerView"), + "function_search_path_mutable" => category!("dblint/splinter/functionSearchPathMutable"), + "rls_disabled_in_public" => category!("dblint/splinter/rlsDisabledInPublic"), + "extension_in_public" => category!("dblint/splinter/extensionInPublic"), + "rls_references_user_metadata" => category!("dblint/splinter/rlsReferencesUserMetadata"), + "materialized_view_in_api" => category!("dblint/splinter/materializedViewInApi"), + "foreign_table_in_api" => category!("dblint/splinter/foreignTableInApi"), + "unsupported_reg_types" => category!("dblint/splinter/unsupportedRegTypes"), + "insecure_queue_exposed_in_api" => category!("dblint/splinter/insecureQueueExposedInApi"), + "table_bloat" => category!("dblint/splinter/tableBloat"), + "fkey_to_auth_unique" => category!("dblint/splinter/fkeyToAuthUnique"), + "extension_versions_outdated" => category!("dblint/splinter/extensionVersionsOutdated"), + _ => category!("dblint/splinter/unknown"), + } +} + +/// Extract common metadata fields and return the rest as additional_metadata +fn extract_metadata_fields( + metadata: &Value, +) -> ( + Option, + Option, + Option, + Option, +) { + if let Some(obj) = metadata.as_object() { + let schema = obj.get("schema").and_then(|v| v.as_str()).map(String::from); + + let object_name = obj.get("name").and_then(|v| v.as_str()).map(String::from); + + let object_type = obj.get("type").and_then(|v| v.as_str()).map(String::from); + + // Create a new object without the common fields + let mut additional = obj.clone(); + additional.remove("schema"); + additional.remove("name"); + additional.remove("type"); + + let additional_metadata = if additional.is_empty() { + None + } else { + Some(Value::Object(additional)) + }; + + (schema, object_name, object_type, additional_metadata) + } else { + (None, None, None, Some(metadata.clone())) + } +} diff --git a/crates/pgls_splinter/src/diagnostics.rs b/crates/pgls_splinter/src/diagnostics.rs new file mode 100644 index 000000000..c88ab945d --- /dev/null +++ b/crates/pgls_splinter/src/diagnostics.rs @@ -0,0 +1,81 @@ +use pgls_diagnostics::{ + Advices, Category, Diagnostic, LogCategory, MessageAndDescription, Severity, Visit, +}; +use serde_json::Value; +use std::io; + +/// A specialized diagnostic for Splinter (database-level linting). +#[derive(Debug, Diagnostic, PartialEq)] +pub struct SplinterDiagnostic { + #[category] + pub category: &'static Category, + + // TODO: add new location type for database objects + // This will map schema + object_name to source code location + // #[location(span)] + // pub span: Option, + #[message] + #[description] + pub message: MessageAndDescription, + + #[severity] + pub severity: Severity, + + #[advice] + pub advices: SplinterAdvices, +} + +/// Advices for Splinter diagnostics, containing database-level issue details +#[derive(Debug, PartialEq)] +pub struct SplinterAdvices { + /// General description of what this rule detects + pub description: String, + + /// Database schema name (e.g., "public", "auth") + pub schema: Option, + + /// Database object name (e.g., table name, view name, function name) + pub object_name: Option, + + /// Type of database object (e.g., "table", "view", "materialized view", "function") + pub object_type: Option, + + /// URL to documentation/remediation guide + pub remediation_url: String, + + /// Additional rule-specific metadata (e.g., fkey_name, column, indexes) + /// This contains fields that don't fit into the common structure + pub additional_metadata: Option, +} + +impl Advices for SplinterAdvices { + fn record(&self, visitor: &mut dyn Visit) -> io::Result<()> { + // Show rule description + visitor.record_log(LogCategory::None, &self.description)?; + + // Show affected database object + if let (Some(schema), Some(name)) = (&self.schema, &self.object_name) { + let type_str = self + .object_type + .as_ref() + .map(|t| format!("{t}: ")) + .unwrap_or_default(); + visitor.record_log(LogCategory::Info, &format!("{type_str}{schema}.{name}"))?; + } + + // Show additional metadata if present + if let Some(metadata) = &self.additional_metadata { + if !metadata.is_null() { + visitor.record_log(LogCategory::None, &format!("{metadata}"))?; + } + } + + // Show remediation URL + visitor.record_log( + LogCategory::Info, + &format!("Documentation: {}", &self.remediation_url), + )?; + + Ok(()) + } +} diff --git a/crates/pgls_splinter/src/lib.rs b/crates/pgls_splinter/src/lib.rs new file mode 100644 index 000000000..11cfb3277 --- /dev/null +++ b/crates/pgls_splinter/src/lib.rs @@ -0,0 +1,48 @@ +mod convert; +mod diagnostics; +mod query; + +use sqlx::PgPool; + +pub use diagnostics::{SplinterAdvices, SplinterDiagnostic}; +pub use query::SplinterQueryResult; + +#[derive(Debug)] +pub struct SplinterParams<'a> { + pub conn: &'a PgPool, +} + +async fn check_required_roles(conn: &PgPool) -> Result { + let required_roles = ["anon", "authenticated", "service_role"]; + + let existing_roles: Vec = + sqlx::query_scalar("SELECT rolname FROM pg_roles WHERE rolname = ANY($1)") + .bind(&required_roles[..]) + .fetch_all(conn) + .await?; + + // Check if all required roles exist + let all_exist = required_roles + .iter() + .all(|role| existing_roles.contains(&(*role).to_string())); + + Ok(all_exist) +} + +pub async fn run_splinter( + params: SplinterParams<'_>, +) -> Result, sqlx::Error> { + // check if required supabase roles exist + // if they don't exist, return empty diagnostics since splinter is supabase-specific + // opened an issue to make it less supabase-specific: https://github.com/supabase/splinter/issues/135 + let has_roles = check_required_roles(params.conn).await?; + if !has_roles { + return Ok(Vec::new()); + } + + let results = query::load_splinter_results(params.conn).await?; + + let diagnostics: Vec = results.into_iter().map(Into::into).collect(); + + Ok(diagnostics) +} diff --git a/crates/pgls_splinter/src/query.rs b/crates/pgls_splinter/src/query.rs new file mode 100644 index 000000000..6336d0353 --- /dev/null +++ b/crates/pgls_splinter/src/query.rs @@ -0,0 +1,57 @@ +use serde_json::Value; +use sqlx::PgPool; + +/// Raw query result from the Splinter SQL query. +/// This struct represents a single linting issue found in the database. +#[derive(Debug)] +pub struct SplinterQueryResult { + /// Unique identifier for the lint rule (e.g., "unindexed_foreign_keys") + pub name: String, + + /// Human-readable title for the rule (e.g., "Unindexed foreign keys") + pub title: String, + + /// Severity level: "INFO", "WARN", or "ERROR" + pub level: String, + + /// Facing: "EXTERNAL" or "INTERNAL" + pub facing: String, + + /// Categories this issue belongs to (e.g., ["PERFORMANCE"], ["SECURITY"]) + pub categories: Vec, + + /// General description of what this rule detects + pub description: String, + + /// Specific detail about this particular violation + pub detail: String, + + /// URL to documentation/remediation guide + pub remediation: String, + + /// Structured metadata about the database objects involved + /// Contains common keys: schema, name, type + /// Plus rule-specific fields like fkey_name, column, indexes, etc. + pub metadata: Value, + + /// Unique cache key for this specific issue + pub cache_key: String, +} + +pub async fn load_splinter_results(pool: &PgPool) -> Result, sqlx::Error> { + let mut tx = pool.begin().await?; + + // this is done by the splinter.sql file normally, but we remove it so that sqlx can work with + // the file properly. + sqlx::query("set local search_path = ''") + .execute(&mut *tx) + .await?; + + let results = sqlx::query_file_as!(SplinterQueryResult, "vendor/splinter.sql") + .fetch_all(&mut *tx) + .await?; + + tx.commit().await?; + + Ok(results) +} diff --git a/crates/pgls_splinter/tests/diagnostics.rs b/crates/pgls_splinter/tests/diagnostics.rs new file mode 100644 index 000000000..730c3adee --- /dev/null +++ b/crates/pgls_splinter/tests/diagnostics.rs @@ -0,0 +1,267 @@ +use pgls_console::fmt::{Formatter, HTML}; +use pgls_diagnostics::{Diagnostic, LogCategory, Visit}; +use pgls_splinter::{SplinterParams, run_splinter}; +use sqlx::PgPool; +use std::fmt::Write; +use std::io; + +struct TestVisitor { + logs: Vec, +} + +impl TestVisitor { + fn new() -> Self { + Self { logs: Vec::new() } + } + + fn into_string(self) -> String { + self.logs.join("\n") + } +} + +impl Visit for TestVisitor { + fn record_log( + &mut self, + category: LogCategory, + text: &dyn pgls_console::fmt::Display, + ) -> io::Result<()> { + let prefix = match category { + LogCategory::None => "", + LogCategory::Info => "[Info] ", + LogCategory::Warn => "[Warn] ", + LogCategory::Error => "[Error] ", + }; + + let mut buffer = vec![]; + let mut writer = HTML::new(&mut buffer); + let mut formatter = Formatter::new(&mut writer); + text.fmt(&mut formatter)?; + + let text_str = String::from_utf8(buffer).unwrap(); + self.logs.push(format!("{prefix}{text_str}")); + Ok(()) + } +} + +struct TestSetup<'a> { + name: &'a str, + setup: &'a str, + test_db: &'a PgPool, +} + +impl TestSetup<'_> { + async fn test(self) { + // Create Supabase-specific roles that splinter expects + sqlx::raw_sql( + r#" + do $$ + begin + if not exists (select from pg_roles where rolname = 'anon') then + create role anon nologin; + end if; + if not exists (select from pg_roles where rolname = 'authenticated') then + create role authenticated nologin; + end if; + if not exists (select from pg_roles where rolname = 'service_role') then + create role service_role nologin; + end if; + end + $$; + "#, + ) + .execute(self.test_db) + .await + .expect("Failed to create Supabase roles"); + + // Run setup SQL + sqlx::raw_sql(self.setup) + .execute(self.test_db) + .await + .expect("Failed to setup test database"); + + // Run splinter checks + let diagnostics = run_splinter(SplinterParams { conn: self.test_db }) + .await + .expect("Failed to run splinter checks"); + + let content = if diagnostics.is_empty() { + String::from("No Diagnostics") + } else { + let mut result = String::new(); + + for (idx, diagnostic) in diagnostics.iter().enumerate() { + if idx > 0 { + writeln!(&mut result).unwrap(); + writeln!(&mut result, "---").unwrap(); + writeln!(&mut result).unwrap(); + } + + // Write category + let category_name = diagnostic.category().map(|c| c.name()).unwrap_or("unknown"); + writeln!(&mut result, "Category: {category_name}").unwrap(); + + // Write severity + writeln!(&mut result, "Severity: {:?}", diagnostic.severity()).unwrap(); + + // Write message + let mut msg_content = vec![]; + let mut writer = HTML::new(&mut msg_content); + let mut formatter = Formatter::new(&mut writer); + diagnostic.message(&mut formatter).unwrap(); + writeln!( + &mut result, + "Message: {}", + String::from_utf8(msg_content).unwrap() + ) + .unwrap(); + + // Write advices using custom visitor + let mut visitor = TestVisitor::new(); + diagnostic.advices(&mut visitor).unwrap(); + let advice_text = visitor.into_string(); + if !advice_text.is_empty() { + writeln!(&mut result, "Advices:\n{advice_text}").unwrap(); + } + } + + result + }; + + insta::with_settings!({ + prepend_module_to_snapshot => false, + }, { + insta::assert_snapshot!(self.name, content); + }); + } +} + +#[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] +async fn unindexed_foreign_key(test_db: PgPool) { + TestSetup { + name: "unindexed_foreign_key", + setup: r#" + create table public.users ( + id serial primary key, + name text not null + ); + + create table public.posts ( + id serial primary key, + user_id integer not null references public.users(id), + title text not null + ); + "#, + test_db: &test_db, + } + .test() + .await; +} + +#[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] +async fn no_primary_key(test_db: PgPool) { + TestSetup { + name: "no_primary_key", + setup: r#" + create table public.articles ( + title text not null, + content text + ); + "#, + test_db: &test_db, + } + .test() + .await; +} + +#[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] +async fn rls_disabled_in_public(test_db: PgPool) { + TestSetup { + name: "rls_disabled_in_public", + setup: r#" + create table public.sensitive_data ( + id serial primary key, + secret text not null + ); + "#, + test_db: &test_db, + } + .test() + .await; +} + +#[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] +async fn policy_exists_rls_disabled(test_db: PgPool) { + TestSetup { + name: "policy_exists_rls_disabled", + setup: r#" + create table public.documents ( + id serial primary key, + content text not null + ); + + create policy "documents_policy" + on public.documents + for select + to public + using (true); + "#, + test_db: &test_db, + } + .test() + .await; +} + +#[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] +async fn no_issues(test_db: PgPool) { + TestSetup { + name: "no_issues", + setup: r#" + create table public.clean_table ( + id serial primary key, + name text not null + ); + "#, + test_db: &test_db, + } + .test() + .await; +} + +#[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] +async fn multiple_issues(test_db: PgPool) { + TestSetup { + name: "multiple_issues", + setup: r#" + -- Table without primary key + create table public.no_pk_table ( + name text + ); + + -- Table with unindexed foreign key + create table public.parent_table ( + id serial primary key + ); + + create table public.child_table ( + id serial primary key, + parent_id integer not null references public.parent_table(id) + ); + "#, + test_db: &test_db, + } + .test() + .await; +} + +#[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] +async fn missing_roles_returns_empty(test_db: PgPool) { + let diagnostics = run_splinter(SplinterParams { conn: &test_db }) + .await + .expect("Should not error when roles are missing"); + + assert!( + diagnostics.is_empty(), + "Expected empty diagnostics when Supabase roles are missing, but got {} diagnostics", + diagnostics.len() + ); +} diff --git a/crates/pgls_splinter/tests/snapshots/multiple_issues.snap b/crates/pgls_splinter/tests/snapshots/multiple_issues.snap new file mode 100644 index 000000000..b214c2417 --- /dev/null +++ b/crates/pgls_splinter/tests/snapshots/multiple_issues.snap @@ -0,0 +1,23 @@ +--- +source: crates/pgls_splinter/tests/diagnostics.rs +expression: content +snapshot_kind: text +--- +Category: dblint/splinter/unindexedForeignKeys +Severity: Information +Message: Table \`public.child_table\` has a foreign key \`child_table_parent_id_fkey\` without a covering index. This can lead to suboptimal query performance. +Advices: +Identifies foreign key constraints without a covering index, which can impact database performance. +[Info] table: public.child_table +{"fkey_name":"child_table_parent_id_fkey","fkey_columns":[2]} +[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys + +--- + +Category: dblint/splinter/noPrimaryKey +Severity: Information +Message: Table \`public.no_pk_table\` does not have a primary key +Advices: +Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale. +[Info] table: public.no_pk_table +[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key diff --git a/crates/pgls_splinter/tests/snapshots/no_issues.snap b/crates/pgls_splinter/tests/snapshots/no_issues.snap new file mode 100644 index 000000000..d9cf288a8 --- /dev/null +++ b/crates/pgls_splinter/tests/snapshots/no_issues.snap @@ -0,0 +1,6 @@ +--- +source: crates/pgls_splinter/tests/diagnostics.rs +expression: content +snapshot_kind: text +--- +No Diagnostics diff --git a/crates/pgls_splinter/tests/snapshots/no_primary_key.snap b/crates/pgls_splinter/tests/snapshots/no_primary_key.snap new file mode 100644 index 000000000..2f9dbf66e --- /dev/null +++ b/crates/pgls_splinter/tests/snapshots/no_primary_key.snap @@ -0,0 +1,12 @@ +--- +source: crates/pgls_splinter/tests/diagnostics.rs +expression: content +snapshot_kind: text +--- +Category: dblint/splinter/noPrimaryKey +Severity: Information +Message: Table \`public.articles\` does not have a primary key +Advices: +Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale. +[Info] table: public.articles +[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key diff --git a/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap b/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap new file mode 100644 index 000000000..f7f57da57 --- /dev/null +++ b/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap @@ -0,0 +1,12 @@ +--- +source: crates/pgls_splinter/tests/diagnostics.rs +expression: content +snapshot_kind: text +--- +Category: dblint/splinter/policyExistsRlsDisabled +Severity: Error +Message: Table \`public.documents\` has RLS policies but RLS is not enabled on the table. Policies include {documents_policy}. +Advices: +Detects cases where row level security (RLS) policies have been created, but RLS has not been enabled for the underlying table. +[Info] table: public.documents +[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled diff --git a/crates/pgls_splinter/tests/snapshots/rls_disabled_in_public.snap b/crates/pgls_splinter/tests/snapshots/rls_disabled_in_public.snap new file mode 100644 index 000000000..d9cf288a8 --- /dev/null +++ b/crates/pgls_splinter/tests/snapshots/rls_disabled_in_public.snap @@ -0,0 +1,6 @@ +--- +source: crates/pgls_splinter/tests/diagnostics.rs +expression: content +snapshot_kind: text +--- +No Diagnostics diff --git a/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap b/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap new file mode 100644 index 000000000..e4f9b5fe9 --- /dev/null +++ b/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap @@ -0,0 +1,13 @@ +--- +source: crates/pgls_splinter/tests/diagnostics.rs +expression: content +snapshot_kind: text +--- +Category: dblint/splinter/unindexedForeignKeys +Severity: Information +Message: Table \`public.posts\` has a foreign key \`posts_user_id_fkey\` without a covering index. This can lead to suboptimal query performance. +Advices: +Identifies foreign key constraints without a covering index, which can impact database performance. +[Info] table: public.posts +{"fkey_name":"posts_user_id_fkey","fkey_columns":[2]} +[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys diff --git a/crates/pgls_splinter/vendor/COMMIT_SHA.txt b/crates/pgls_splinter/vendor/COMMIT_SHA.txt new file mode 100644 index 000000000..e211f5f15 --- /dev/null +++ b/crates/pgls_splinter/vendor/COMMIT_SHA.txt @@ -0,0 +1 @@ +27ea2ece65464213e466cd969cc61b6940d16219 diff --git a/crates/pgls_splinter/vendor/splinter.sql b/crates/pgls_splinter/vendor/splinter.sql new file mode 100644 index 000000000..7f479898e --- /dev/null +++ b/crates/pgls_splinter/vendor/splinter.sql @@ -0,0 +1,1149 @@ + +( +with foreign_keys as ( + select + cl.relnamespace::regnamespace::text as schema_name, + cl.relname as table_name, + cl.oid as table_oid, + ct.conname as fkey_name, + ct.conkey as col_attnums + from + pg_catalog.pg_constraint ct + join pg_catalog.pg_class cl -- fkey owning table + on ct.conrelid = cl.oid + left join pg_catalog.pg_depend d + on d.objid = cl.oid + and d.deptype = 'e' + where + ct.contype = 'f' -- foreign key constraints + and d.objid is null -- exclude tables that are dependencies of extensions + and cl.relnamespace::regnamespace::text not in ( + 'pg_catalog', 'information_schema', 'auth', 'storage', 'vault', 'extensions' + ) +), +index_ as ( + select + pi.indrelid as table_oid, + indexrelid::regclass as index_, + string_to_array(indkey::text, ' ')::smallint[] as col_attnums + from + pg_catalog.pg_index pi + where + indisvalid +) +select + 'unindexed_foreign_keys' as "name!", + 'Unindexed foreign keys' as "title!", + 'INFO' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Identifies foreign key constraints without a covering index, which can impact database performance.' as "description!", + format( + 'Table \`%s.%s\` has a foreign key \`%s\` without a covering index. This can lead to suboptimal query performance.', + fk.schema_name, + fk.table_name, + fk.fkey_name + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys' as "remediation!", + jsonb_build_object( + 'schema', fk.schema_name, + 'name', fk.table_name, + 'type', 'table', + 'fkey_name', fk.fkey_name, + 'fkey_columns', fk.col_attnums + ) as "metadata!", + format('unindexed_foreign_keys_%s_%s_%s', fk.schema_name, fk.table_name, fk.fkey_name) as "cache_key!" +from + foreign_keys fk + left join index_ idx + on fk.table_oid = idx.table_oid + and fk.col_attnums = idx.col_attnums[1:array_length(fk.col_attnums, 1)] + left join pg_catalog.pg_depend dep + on idx.table_oid = dep.objid + and dep.deptype = 'e' +where + idx.index_ is null + and fk.schema_name not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null -- exclude tables owned by extensions +order by + fk.schema_name, + fk.table_name, + fk.fkey_name) +union all +( +select + 'auth_users_exposed' as "name!", + 'Exposed Auth Users' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects if auth.users is exposed to anon or authenticated roles via a view or materialized view in schemas exposed to PostgREST, potentially compromising user data security.' as "description!", + format( + 'View/Materialized View "%s" in the public schema may expose \`auth.users\` data to anon or authenticated roles.', + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'view', + 'exposed_to', array_remove(array_agg(DISTINCT case when pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') then 'anon' when pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') then 'authenticated' end), null) + ) as "metadata!", + format('auth_users_exposed_%s_%s', n.nspname, c.relname) as "cache_key!" +from + -- Identify the oid for auth.users + pg_catalog.pg_class auth_users_pg_class + join pg_catalog.pg_namespace auth_users_pg_namespace + on auth_users_pg_class.relnamespace = auth_users_pg_namespace.oid + and auth_users_pg_class.relname = 'users' + and auth_users_pg_namespace.nspname = 'auth' + -- Depends on auth.users + join pg_catalog.pg_depend d + on d.refobjid = auth_users_pg_class.oid + join pg_catalog.pg_rewrite r + on r.oid = d.objid + join pg_catalog.pg_class c + on c.oid = r.ev_class + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + join pg_catalog.pg_class pg_class_auth_users + on d.refobjid = pg_class_auth_users.oid +where + d.deptype = 'n' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + -- Exclude self + and c.relname <> '0002_auth_users_exposed' + -- There are 3 insecure configurations + and + ( + -- Materialized views don't support RLS so this is insecure by default + (c.relkind in ('m')) -- m for materialized view + or + -- Standard View, accessible to anon or authenticated that is security_definer + ( + c.relkind = 'v' -- v for view + -- Exclude security invoker views + and not ( + lower(coalesce(c.reloptions::text,'{}'))::text[] + && array[ + 'security_invoker=1', + 'security_invoker=true', + 'security_invoker=yes', + 'security_invoker=on' + ] + ) + ) + or + -- Standard View, security invoker, but no RLS enabled on auth.users + ( + c.relkind in ('v') -- v for view + -- is security invoker + and ( + lower(coalesce(c.reloptions::text,'{}'))::text[] + && array[ + 'security_invoker=1', + 'security_invoker=true', + 'security_invoker=yes', + 'security_invoker=on' + ] + ) + and not pg_class_auth_users.relrowsecurity + ) + ) +group by + n.nspname, + c.relname, + c.oid) +union all +( +with policies as ( + select + nsp.nspname as schema_name, + pb.tablename as table_name, + pc.relrowsecurity as is_rls_active, + polname as policy_name, + polpermissive as is_permissive, -- if not, then restrictive + (select array_agg(r::regrole) from unnest(polroles) as x(r)) as roles, + case polcmd + when 'r' then 'SELECT' + when 'a' then 'INSERT' + when 'w' then 'UPDATE' + when 'd' then 'DELETE' + when '*' then 'ALL' + end as command, + qual, + with_check + from + pg_catalog.pg_policy pa + join pg_catalog.pg_class pc + on pa.polrelid = pc.oid + join pg_catalog.pg_namespace nsp + on pc.relnamespace = nsp.oid + join pg_catalog.pg_policies pb + on pc.relname = pb.tablename + and nsp.nspname = pb.schemaname + and pa.polname = pb.policyname +) +select + 'auth_rls_initplan' as "name!", + 'Auth RLS Initialization Plan' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Detects if calls to \`current_setting()\` and \`auth.()\` in RLS policies are being unnecessarily re-evaluated for each row' as "description!", + format( + 'Table \`%s.%s\` has a row level security policy \`%s\` that re-evaluates current_setting() or auth.() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \`auth.()\` with \`(select auth.())\`. See [docs](https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select) for more info.', + schema_name, + table_name, + policy_name + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan' as "remediation!", + jsonb_build_object( + 'schema', schema_name, + 'name', table_name, + 'type', 'table' + ) as "metadata!", + format('auth_rls_init_plan_%s_%s_%s', schema_name, table_name, policy_name) as "cache_key!" +from + policies +where + is_rls_active + -- NOTE: does not include realtime in support of monitoring policies on realtime.messages + and schema_name not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and ( + -- Example: auth.uid() + ( + qual like '%auth.uid()%' + and lower(qual) not like '%select auth.uid()%' + ) + or ( + qual like '%auth.jwt()%' + and lower(qual) not like '%select auth.jwt()%' + ) + or ( + qual like '%auth.role()%' + and lower(qual) not like '%select auth.role()%' + ) + or ( + qual like '%auth.email()%' + and lower(qual) not like '%select auth.email()%' + ) + or ( + qual like '%current\_setting(%)%' + and lower(qual) not like '%select current\_setting(%)%' + ) + or ( + with_check like '%auth.uid()%' + and lower(with_check) not like '%select auth.uid()%' + ) + or ( + with_check like '%auth.jwt()%' + and lower(with_check) not like '%select auth.jwt()%' + ) + or ( + with_check like '%auth.role()%' + and lower(with_check) not like '%select auth.role()%' + ) + or ( + with_check like '%auth.email()%' + and lower(with_check) not like '%select auth.email()%' + ) + or ( + with_check like '%current\_setting(%)%' + and lower(with_check) not like '%select current\_setting(%)%' + ) + )) +union all +( +select + 'no_primary_key' as "name!", + 'No Primary Key' as "title!", + 'INFO' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale.' as "description!", + format( + 'Table \`%s.%s\` does not have a primary key', + pgns.nspname, + pgc.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key' as "remediation!", + jsonb_build_object( + 'schema', pgns.nspname, + 'name', pgc.relname, + 'type', 'table' + ) as "metadata!", + format( + 'no_primary_key_%s_%s', + pgns.nspname, + pgc.relname + ) as "cache_key!" +from + pg_catalog.pg_class pgc + join pg_catalog.pg_namespace pgns + on pgns.oid = pgc.relnamespace + left join pg_catalog.pg_index pgi + on pgi.indrelid = pgc.oid + left join pg_catalog.pg_depend dep + on pgc.oid = dep.objid + and dep.deptype = 'e' +where + pgc.relkind = 'r' -- regular tables + and pgns.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null -- exclude tables owned by extensions +group by + pgc.oid, + pgns.nspname, + pgc.relname +having + max(coalesce(pgi.indisprimary, false)::int) = 0) +union all +( +select + 'unused_index' as "name!", + 'Unused Index' as "title!", + 'INFO' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Detects if an index has never been used and may be a candidate for removal.' as "description!", + format( + 'Index \`%s\` on table \`%s.%s\` has not been used', + psui.indexrelname, + psui.schemaname, + psui.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index' as "remediation!", + jsonb_build_object( + 'schema', psui.schemaname, + 'name', psui.relname, + 'type', 'table' + ) as "metadata!", + format( + 'unused_index_%s_%s_%s', + psui.schemaname, + psui.relname, + psui.indexrelname + ) as "cache_key!" + +from + pg_catalog.pg_stat_user_indexes psui + join pg_catalog.pg_index pi + on psui.indexrelid = pi.indexrelid + left join pg_catalog.pg_depend dep + on psui.relid = dep.objid + and dep.deptype = 'e' +where + psui.idx_scan = 0 + and not pi.indisunique + and not pi.indisprimary + and dep.objid is null -- exclude tables owned by extensions + and psui.schemaname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + )) +union all +( +select + 'multiple_permissive_policies' as "name!", + 'Multiple Permissive Policies' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Detects if multiple permissive row level security policies are present on a table for the same \`role\` and \`action\` (e.g. insert). Multiple permissive policies are suboptimal for performance as each policy must be executed for every relevant query.' as "description!", + format( + 'Table \`%s.%s\` has multiple permissive policies for role \`%s\` for action \`%s\`. Policies include \`%s\`', + n.nspname, + c.relname, + r.rolname, + act.cmd, + array_agg(p.polname order by p.polname) + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'table' + ) as "metadata!", + format( + 'multiple_permissive_policies_%s_%s_%s_%s', + n.nspname, + c.relname, + r.rolname, + act.cmd + ) as "cache_key!" +from + pg_catalog.pg_policy p + join pg_catalog.pg_class c + on p.polrelid = c.oid + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid + join pg_catalog.pg_roles r + on p.polroles @> array[r.oid] + or p.polroles = array[0::oid] + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e', + lateral ( + select x.cmd + from unnest(( + select + case p.polcmd + when 'r' then array['SELECT'] + when 'a' then array['INSERT'] + when 'w' then array['UPDATE'] + when 'd' then array['DELETE'] + when '*' then array['SELECT', 'INSERT', 'UPDATE', 'DELETE'] + else array['ERROR'] + end as actions + )) x(cmd) + ) act(cmd) +where + c.relkind = 'r' -- regular tables + and p.polpermissive -- policy is permissive + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and r.rolname not like 'pg_%' + and r.rolname not like 'supabase%admin' + and not r.rolbypassrls + and dep.objid is null -- exclude tables owned by extensions +group by + n.nspname, + c.relname, + r.rolname, + act.cmd +having + count(1) > 1) +union all +( +select + 'policy_exists_rls_disabled' as "name!", + 'Policy Exists RLS Disabled' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects cases where row level security (RLS) policies have been created, but RLS has not been enabled for the underlying table.' as "description!", + format( + 'Table \`%s.%s\` has RLS policies but RLS is not enabled on the table. Policies include %s.', + n.nspname, + c.relname, + array_agg(p.polname order by p.polname) + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'table' + ) as "metadata!", + format( + 'policy_exists_rls_disabled_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_policy p + join pg_catalog.pg_class c + on p.polrelid = c.oid + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'r' -- regular tables + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + -- RLS is disabled + and not c.relrowsecurity + and dep.objid is null -- exclude tables owned by extensions +group by + n.nspname, + c.relname) +union all +( +select + 'rls_enabled_no_policy' as "name!", + 'RLS Enabled No Policy' as "title!", + 'INFO' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects cases where row level security (RLS) has been enabled on a table but no RLS policies have been created.' as "description!", + format( + 'Table \`%s.%s\` has RLS enabled, but no policies exist', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'table' + ) as "metadata!", + format( + 'rls_enabled_no_policy_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + left join pg_catalog.pg_policy p + on p.polrelid = c.oid + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'r' -- regular tables + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + -- RLS is enabled + and c.relrowsecurity + and p.polname is null + and dep.objid is null -- exclude tables owned by extensions +group by + n.nspname, + c.relname) +union all +( +select + 'duplicate_index' as "name!", + 'Duplicate Index' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Detects cases where two ore more identical indexes exist.' as "description!", + format( + 'Table \`%s.%s\` has identical indexes %s. Drop all except one of them', + n.nspname, + c.relname, + array_agg(pi.indexname order by pi.indexname) + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', case + when c.relkind = 'r' then 'table' + when c.relkind = 'm' then 'materialized view' + else 'ERROR' + end, + 'indexes', array_agg(pi.indexname order by pi.indexname) + ) as "metadata!", + format( + 'duplicate_index_%s_%s_%s', + n.nspname, + c.relname, + array_agg(pi.indexname order by pi.indexname) + ) as "cache_key!" +from + pg_catalog.pg_indexes pi + join pg_catalog.pg_namespace n + on n.nspname = pi.schemaname + join pg_catalog.pg_class c + on pi.tablename = c.relname + and n.oid = c.relnamespace + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind in ('r', 'm') -- tables and materialized views + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null -- exclude tables owned by extensions +group by + n.nspname, + c.relkind, + c.relname, + replace(pi.indexdef, pi.indexname, '') +having + count(*) > 1) +union all +( +select + 'security_definer_view' as "name!", + 'Security Definer View' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects views defined with the SECURITY DEFINER property. These views enforce Postgres permissions and row level security policies (RLS) of the view creator, rather than that of the querying user' as "description!", + format( + 'View \`%s.%s\` is defined with the SECURITY DEFINER property', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'view' + ) as "metadata!", + format( + 'security_definer_view_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'v' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and substring(pg_catalog.version() from 'PostgreSQL ([0-9]+)') >= '15' -- security invoker was added in pg15 + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null -- exclude views owned by extensions + and not ( + lower(coalesce(c.reloptions::text,'{}'))::text[] + && array[ + 'security_invoker=1', + 'security_invoker=true', + 'security_invoker=yes', + 'security_invoker=on' + ] + )) +union all +( +select + 'function_search_path_mutable' as "name!", + 'Function Search Path Mutable' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects functions where the search_path parameter is not set.' as "description!", + format( + 'Function \`%s.%s\` has a role mutable search_path', + n.nspname, + p.proname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', p.proname, + 'type', 'function' + ) as "metadata!", + format( + 'function_search_path_mutable_%s_%s_%s', + n.nspname, + p.proname, + md5(p.prosrc) -- required when function is polymorphic + ) as "cache_key!" +from + pg_catalog.pg_proc p + join pg_catalog.pg_namespace n + on p.pronamespace = n.oid + left join pg_catalog.pg_depend dep + on p.oid = dep.objid + and dep.deptype = 'e' +where + n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null -- exclude functions owned by extensions + -- Search path not set + and not exists ( + select 1 + from unnest(coalesce(p.proconfig, '{}')) as config + where config like 'search_path=%' + )) +union all +( +select + 'rls_disabled_in_public' as "name!", + 'RLS Disabled in Public' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects cases where row level security (RLS) has not been enabled on tables in schemas exposed to PostgREST' as "description!", + format( + 'Table \`%s.%s\` is public, but RLS has not been enabled.', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'table' + ) as "metadata!", + format( + 'rls_disabled_in_public_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid +where + c.relkind = 'r' -- regular tables + -- RLS is disabled + and not c.relrowsecurity + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + )) +union all +( +select + 'extension_in_public' as "name!", + 'Extension in Public' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects extensions installed in the \`public\` schema.' as "description!", + format( + 'Extension \`%s\` is installed in the public schema. Move it to another schema.', + pe.extname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public' as "remediation!", + jsonb_build_object( + 'schema', pe.extnamespace::regnamespace, + 'name', pe.extname, + 'type', 'extension' + ) as "metadata!", + format( + 'extension_in_public_%s', + pe.extname + ) as "cache_key!" +from + pg_catalog.pg_extension pe +where + -- plpgsql is installed by default in public and outside user control + -- confirmed safe + pe.extname not in ('plpgsql') + -- Scoping this to public is not optimal. Ideally we would use the postgres + -- search path. That currently isn't available via SQL. In other lints + -- we have used has_schema_privilege('anon', 'extensions', 'USAGE') but that + -- is not appropriate here as it would evaluate true for the extensions schema + and pe.extnamespace::regnamespace::text = 'public') +union all +( +with policies as ( + select + nsp.nspname as schema_name, + pb.tablename as table_name, + polname as policy_name, + qual, + with_check + from + pg_catalog.pg_policy pa + join pg_catalog.pg_class pc + on pa.polrelid = pc.oid + join pg_catalog.pg_namespace nsp + on pc.relnamespace = nsp.oid + join pg_catalog.pg_policies pb + on pc.relname = pb.tablename + and nsp.nspname = pb.schemaname + and pa.polname = pb.policyname +) +select + 'rls_references_user_metadata' as "name!", + 'RLS references user metadata' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects when Supabase Auth user_metadata is referenced insecurely in a row level security (RLS) policy.' as "description!", + format( + 'Table \`%s.%s\` has a row level security policy \`%s\` that references Supabase Auth \`user_metadata\`. \`user_metadata\` is editable by end users and should never be used in a security context.', + schema_name, + table_name, + policy_name + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata' as "remediation!", + jsonb_build_object( + 'schema', schema_name, + 'name', table_name, + 'type', 'table' + ) as "metadata!", + format('rls_references_user_metadata_%s_%s_%s', schema_name, table_name, policy_name) as "cache_key!" +from + policies +where + schema_name not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and ( + -- Example: auth.jwt() -> 'user_metadata' + -- False positives are possible, but it isn't practical to string match + -- If false positive rate is too high, this expression can iterate + qual like '%auth.jwt()%user_metadata%' + or qual like '%current_setting(%request.jwt.claims%)%user_metadata%' + or with_check like '%auth.jwt()%user_metadata%' + or with_check like '%current_setting(%request.jwt.claims%)%user_metadata%' + )) +union all +( +select + 'materialized_view_in_api' as "name!", + 'Materialized View in API' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects materialized views that are accessible over the Data APIs.' as "description!", + format( + 'Materialized view \`%s.%s\` is selectable by anon or authenticated roles', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'materialized view' + ) as "metadata!", + format( + 'materialized_view_in_api_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'm' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null) +union all +( +select + 'foreign_table_in_api' as "name!", + 'Foreign Table in API' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects foreign tables that are accessible over APIs. Foreign tables do not respect row level security policies.' as "description!", + format( + 'Foreign table \`%s.%s\` is accessible over APIs', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'foreign table' + ) as "metadata!", + format( + 'foreign_table_in_api_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'f' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null) +union all +( +select + 'unsupported_reg_types' as "name!", + 'Unsupported reg types' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Identifies columns using unsupported reg* types outside pg_catalog schema, which prevents database upgrades using pg_upgrade.' as "description!", + format( + 'Table \`%s.%s\` has a column \`%s\` with unsupported reg* type \`%s\`.', + n.nspname, + c.relname, + a.attname, + t.typname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'column', a.attname, + 'type', 'table' + ) as "metadata!", + format( + 'unsupported_reg_types_%s_%s_%s', + n.nspname, + c.relname, + a.attname + ) AS cache_key +from + pg_catalog.pg_attribute a + join pg_catalog.pg_class c + on a.attrelid = c.oid + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid + join pg_catalog.pg_type t + on a.atttypid = t.oid + join pg_catalog.pg_namespace tn + on t.typnamespace = tn.oid +where + tn.nspname = 'pg_catalog' + and t.typname in ('regcollation', 'regconfig', 'regdictionary', 'regnamespace', 'regoper', 'regoperator', 'regproc', 'regprocedure') + and n.nspname not in ('pg_catalog', 'information_schema', 'pgsodium')) +union all +( +select + 'insecure_queue_exposed_in_api' as "name!", + 'Insecure Queue Exposed in API' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects cases where an insecure Queue is exposed over Data APIs' as "description!", + format( + 'Table \`%s.%s\` is public, but RLS has not been enabled.', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'table' + ) as "metadata!", + format( + 'rls_disabled_in_public_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid +where + c.relkind in ('r', 'I') -- regular or partitioned tables + and not c.relrowsecurity -- RLS is disabled + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = 'pgmq' -- tables in the pgmq schema + and c.relname like 'q_%' -- only queue tables + -- Constant requirements + and 'pgmq_public' = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))) +union all +( +with constants as ( + select current_setting('block_size')::numeric as bs, 23 as hdr, 4 as ma +), + +bloat_info as ( + select + ma, + bs, + schemaname, + tablename, + (datawidth + (hdr + ma - (case when hdr % ma = 0 then ma else hdr % ma end)))::numeric as datahdr, + (maxfracsum * (nullhdr + ma - (case when nullhdr % ma = 0 then ma else nullhdr % ma end))) as nullhdr2 + from ( + select + schemaname, + tablename, + hdr, + ma, + bs, + sum((1 - null_frac) * avg_width) as datawidth, + max(null_frac) as maxfracsum, + hdr + ( + select 1 + count(*) / 8 + from pg_stats s2 + where + null_frac <> 0 + and s2.schemaname = s.schemaname + and s2.tablename = s.tablename + ) as nullhdr + from pg_stats s, constants + group by 1, 2, 3, 4, 5 + ) as foo +), + +table_bloat as ( + select + schemaname, + tablename, + cc.relpages, + bs, + ceil((cc.reltuples * ((datahdr + ma - + (case when datahdr % ma = 0 then ma else datahdr % ma end)) + nullhdr2 + 4)) / (bs - 20::float)) as otta + from + bloat_info + join pg_class cc + on cc.relname = bloat_info.tablename + join pg_namespace nn + on cc.relnamespace = nn.oid + and nn.nspname = bloat_info.schemaname + and nn.nspname <> 'information_schema' + where + cc.relkind = 'r' + and cc.relam = (select oid from pg_am where amname = 'heap') +), + +bloat_data as ( + select + 'table' as type, + schemaname, + tablename as object_name, + round(case when otta = 0 then 0.0 else table_bloat.relpages / otta::numeric end, 1) as bloat, + case when relpages < otta then 0 else (bs * (table_bloat.relpages - otta)::bigint)::bigint end as raw_waste + from + table_bloat +) + +select + 'table_bloat' as "name!", + 'Table Bloat' as "title!", + 'INFO' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Detects if a table has excess bloat and may benefit from maintenance operations like vacuum full or cluster.' as "description!", + format( + 'Table `%s`.`%s` has excessive bloat', + bloat_data.schemaname, + bloat_data.object_name + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat' as "remediation!", + jsonb_build_object( + 'schema', bloat_data.schemaname, + 'name', bloat_data.object_name, + 'type', bloat_data.type + ) as "metadata!", + format( + 'table_bloat_%s_%s', + bloat_data.schemaname, + bloat_data.object_name + ) as "cache_key!" +from + bloat_data +where + bloat > 70.0 + and raw_waste > (20 * 1024 * 1024) -- filter for waste > 200 MB +order by + schemaname, + object_name) +union all +( +select + 'fkey_to_auth_unique' as "name!", + 'Foreign Key to Auth Unique Constraint' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects user defined foreign keys to unique constraints in the auth schema.' as "description!", + format( + 'Table `%s`.`%s` has a foreign key `%s` referencing an auth unique constraint', + n.nspname, -- referencing schema + c_rel.relname, -- referencing table + c.conname -- fkey name + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c_rel.relname, + 'foreign_key', c.conname + ) as "metadata!", + format( + 'fkey_to_auth_unique_%s_%s_%s', + n.nspname, -- referencing schema + c_rel.relname, -- referencing table + c.conname + ) as "cache_key!" +from + pg_catalog.pg_constraint c + join pg_catalog.pg_class c_rel + on c.conrelid = c_rel.oid + join pg_catalog.pg_namespace n + on c_rel.relnamespace = n.oid + join pg_catalog.pg_class ref_rel + on c.confrelid = ref_rel.oid + join pg_catalog.pg_namespace cn + on ref_rel.relnamespace = cn.oid + join pg_catalog.pg_index i + on c.conindid = i.indexrelid +where c.contype = 'f' + and cn.nspname = 'auth' + and i.indisunique + and not i.indisprimary) +union all +( +select + 'extension_versions_outdated' as "name!", + 'Extension Versions Outdated' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects extensions that are not using the default (recommended) version.' as "description!", + format( + 'Extension `%s` is using version `%s` but version `%s` is available. Using outdated extension versions may expose the database to security vulnerabilities.', + ext.name, + ext.installed_version, + ext.default_version + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated' as "remediation!", + jsonb_build_object( + 'extension_name', ext.name, + 'installed_version', ext.installed_version, + 'default_version', ext.default_version + ) as "metadata!", + format( + 'extension_versions_outdated_%s_%s', + ext.name, + ext.installed_version + ) as "cache_key!" +from + pg_catalog.pg_available_extensions ext +join + -- ignore versions not in pg_available_extension_versions + -- e.g. residue of pg_upgrade + pg_catalog.pg_available_extension_versions extv + on extv.name = ext.name and extv.installed +where + ext.installed_version is not null + and ext.default_version is not null + and ext.installed_version != ext.default_version +order by + ext.name) \ No newline at end of file diff --git a/justfile b/justfile index 81e9d78d1..8129627b1 100644 --- a/justfile +++ b/justfile @@ -28,6 +28,7 @@ gen-lint: cargo run -p xtask_codegen -- analyser cargo run -p xtask_codegen -- configuration cargo run -p xtask_codegen -- bindings + cargo run -p xtask_codegen -- splinter cargo run -p rules_check cargo run -p docs_codegen just format @@ -110,6 +111,7 @@ ready: cargo run -p xtask_codegen -- configuration cargo run -p docs_codegen cargo run -p xtask_codegen -- bindings + cargo run -p xtask_codegen -- splinter cargo sqlx prepare --workspace just lint-fix just format diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs new file mode 100644 index 000000000..17d35503a --- /dev/null +++ b/xtask/codegen/src/generate_splinter.rs @@ -0,0 +1,166 @@ +use anyhow::{Context, Result}; +use biome_string_case::Case; +use std::collections::BTreeMap; +use std::fs; +use xtask::{glue::fs2, project_root}; + +/// Generate splinter categories from the SQL file +pub fn generate_splinter() -> Result<()> { + let sql_path = project_root().join("crates/pgls_splinter/vendor/splinter.sql"); + let sql_content = fs::read_to_string(&sql_path) + .with_context(|| format!("Failed to read SQL file at {:?}", sql_path))?; + + let rules = extract_rules_from_sql(&sql_content)?; + + update_categories_file(rules)?; + + Ok(()) +} + +/// Extract rule information from the SQL file +fn extract_rules_from_sql(content: &str) -> Result> { + let mut rules = BTreeMap::new(); + + let lines: Vec<&str> = content.lines().collect(); + let mut i = 0; + + while i < lines.len() { + let line = lines[i].trim(); + + // Look for pattern: 'rule_name' as "name!", + if line.contains(" as \"name!\"") { + if let Some(name) = extract_string_literal(line) { + // Look ahead for remediation URL + let mut remediation_url = None; + for j in i..std::cmp::min(i + 30, lines.len()) { + let next_line = lines[j].trim(); + if next_line.contains(" as \"remediation!\"") { + remediation_url = extract_string_literal(next_line); + break; + } + } + + let url = remediation_url.with_context(|| { + format!("Failed to find remediation URL for rule '{}'", name) + })?; + + rules.insert( + name.clone(), + RuleInfo { + snake_case: name.clone(), + camel_case: snake_to_camel_case(&name), + url, + }, + ); + } + } + + i += 1; + } + + // Add the "unknown" fallback rule + rules.insert( + "unknown".to_string(), + RuleInfo { + snake_case: "unknown".to_string(), + camel_case: "unknown".to_string(), + url: "https://pg-language-server.com/latest".to_string(), + }, + ); + + Ok(rules) +} + +/// Extract a string literal from a line like "'some_string' as ..." +fn extract_string_literal(line: &str) -> Option { + let trimmed = line.trim(); + + if let Some(start_single) = trimmed.find('\'') { + if let Some(end) = trimmed[start_single + 1..].find('\'') { + return Some(trimmed[start_single + 1..start_single + 1 + end].to_string()); + } + } + + None +} + +/// Convert snake_case to camelCase +fn snake_to_camel_case(s: &str) -> String { + Case::Camel.convert(s) +} + +struct RuleInfo { + #[allow(dead_code)] + snake_case: String, + camel_case: String, + url: String, +} + +/// Update the categories.rs file with splinter rules +fn update_categories_file(rules: BTreeMap) -> Result<()> { + let categories_path = + project_root().join("crates/pgls_diagnostics_categories/src/categories.rs"); + + let content = fs2::read_to_string(&categories_path)?; + + // Generate splinter rule entries + let mut splinter_rules: Vec = rules + .values() + .map(|rule| { + format!( + " \"dblint/splinter/{}\": \"{}\",", + rule.camel_case, rule.url + ) + }) + .collect(); + + splinter_rules.sort(); + let splinter_entries = splinter_rules.join("\n"); + + // Replace content between splinter rules markers + let rules_start = "// splinter rules start"; + let rules_end = "// splinter rules end"; + + let new_content = replace_between_markers( + &content, + rules_start, + rules_end, + &format!("\n{}\n ", splinter_entries), + )?; + + // Replace content between splinter groups markers + let groups_start = "// splinter groups start"; + let groups_end = "// splinter groups end"; + + let groups_content = "\n \"dblint\",\n \"dblint/splinter\",\n "; + + let new_content = + replace_between_markers(&new_content, groups_start, groups_end, groups_content)?; + + fs2::write(categories_path, new_content)?; + + Ok(()) +} + +/// Replace content between two markers +fn replace_between_markers( + content: &str, + start_marker: &str, + end_marker: &str, + new_content: &str, +) -> Result { + let start_pos = content + .find(start_marker) + .with_context(|| format!("Could not find '{}' marker", start_marker))?; + + let end_pos = content + .find(end_marker) + .with_context(|| format!("Could not find '{}' marker", end_marker))?; + + let mut result = String::new(); + result.push_str(&content[..start_pos + start_marker.len()]); + result.push_str(new_content); + result.push_str(&content[end_pos..]); + + Ok(result) +} diff --git a/xtask/codegen/src/lib.rs b/xtask/codegen/src/lib.rs index d095cce9a..661b9f94c 100644 --- a/xtask/codegen/src/lib.rs +++ b/xtask/codegen/src/lib.rs @@ -5,12 +5,14 @@ mod generate_bindings; mod generate_configuration; mod generate_crate; mod generate_new_analyser_rule; +mod generate_splinter; pub use self::generate_analyser::generate_analyser; pub use self::generate_bindings::generate_bindings; pub use self::generate_configuration::generate_rules_configuration; pub use self::generate_crate::generate_crate; pub use self::generate_new_analyser_rule::generate_new_analyser_rule; +pub use self::generate_splinter::generate_splinter; use bpaf::Bpaf; use generate_new_analyser_rule::Category; use pgls_diagnostics::Severity; @@ -90,4 +92,7 @@ pub enum TaskCommand { #[bpaf(long("severity"), fallback(Severity::Error))] severity: Severity, }, + /// Generate splinter categories from the SQL file + #[bpaf(command)] + Splinter, } diff --git a/xtask/codegen/src/main.rs b/xtask/codegen/src/main.rs index 4ff33c21b..43d11b44c 100644 --- a/xtask/codegen/src/main.rs +++ b/xtask/codegen/src/main.rs @@ -3,7 +3,7 @@ use xtask::{project_root, pushd, Result}; use xtask_codegen::{ generate_analyser, generate_bindings, generate_crate, generate_new_analyser_rule, - generate_rules_configuration, task_command, TaskCommand, + generate_rules_configuration, generate_splinter, task_command, TaskCommand, }; fn main() -> Result<()> { @@ -31,6 +31,9 @@ fn main() -> Result<()> { TaskCommand::Bindings => { generate_bindings(Overwrite)?; } + TaskCommand::Splinter => { + generate_splinter()?; + } } Ok(()) From 9d34d82cef7601dc24a7570bd0a5824a9ebb4b8a Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 20:14:07 +0100 Subject: [PATCH 02/17] progress --- ...7301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json | 0 1 file changed, 0 insertions(+), 0 deletions(-) rename {crates/pgls_splinter/.sqlx => .sqlx}/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json (100%) diff --git a/crates/pgls_splinter/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json b/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json similarity index 100% rename from crates/pgls_splinter/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json rename to .sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json From f3fd30c39898b6a6fe2677c4d3925f637bf4f063 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 20:18:35 +0100 Subject: [PATCH 03/17] progress --- .../src/categories.rs | 7 ++--- .../backend-jsonrpc/src/workspace.ts | 26 ++++++++++++++++++- .../backend-jsonrpc/src/workspace.ts | 26 ++++++++++++++++++- xtask/codegen/src/generate_splinter.rs | 9 ------- 4 files changed, 52 insertions(+), 16 deletions(-) diff --git a/crates/pgls_diagnostics_categories/src/categories.rs b/crates/pgls_diagnostics_categories/src/categories.rs index 78619c8e8..7cea0ea7a 100644 --- a/crates/pgls_diagnostics_categories/src/categories.rs +++ b/crates/pgls_diagnostics_categories/src/categories.rs @@ -92,9 +92,6 @@ define_categories! { "lint", "lint/performance", "lint/safety", - // splinter groups start - "dblint", - "dblint/splinter", - // splinter groups end // Lint groups end -} \ No newline at end of file +} + diff --git a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts index 701554f89..7cebb9bda 100644 --- a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts @@ -95,6 +95,28 @@ export type Category = | "lint/safety/requireConcurrentIndexDeletion" | "lint/safety/runningStatementWhileHoldingAccessExclusive" | "lint/safety/transactionNesting" + | "dblint/splinter/authRlsInitplan" + | "dblint/splinter/authUsersExposed" + | "dblint/splinter/duplicateIndex" + | "dblint/splinter/extensionInPublic" + | "dblint/splinter/extensionVersionsOutdated" + | "dblint/splinter/fkeyToAuthUnique" + | "dblint/splinter/foreignTableInApi" + | "dblint/splinter/functionSearchPathMutable" + | "dblint/splinter/insecureQueueExposedInApi" + | "dblint/splinter/materializedViewInApi" + | "dblint/splinter/multiplePermissivePolicies" + | "dblint/splinter/noPrimaryKey" + | "dblint/splinter/policyExistsRlsDisabled" + | "dblint/splinter/rlsDisabledInPublic" + | "dblint/splinter/rlsEnabledNoPolicy" + | "dblint/splinter/rlsReferencesUserMetadata" + | "dblint/splinter/securityDefinerView" + | "dblint/splinter/tableBloat" + | "dblint/splinter/unindexedForeignKeys" + | "dblint/splinter/unknown" + | "dblint/splinter/unsupportedRegTypes" + | "dblint/splinter/unusedIndex" | "stdin" | "check" | "configuration" @@ -111,7 +133,9 @@ export type Category = | "dummy" | "lint" | "lint/performance" - | "lint/safety"; + | "lint/safety" + | "dblint" + | "dblint/splinter"; export interface Location { path?: Resource_for_String; sourceCode?: string; diff --git a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts index 701554f89..7cebb9bda 100644 --- a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts @@ -95,6 +95,28 @@ export type Category = | "lint/safety/requireConcurrentIndexDeletion" | "lint/safety/runningStatementWhileHoldingAccessExclusive" | "lint/safety/transactionNesting" + | "dblint/splinter/authRlsInitplan" + | "dblint/splinter/authUsersExposed" + | "dblint/splinter/duplicateIndex" + | "dblint/splinter/extensionInPublic" + | "dblint/splinter/extensionVersionsOutdated" + | "dblint/splinter/fkeyToAuthUnique" + | "dblint/splinter/foreignTableInApi" + | "dblint/splinter/functionSearchPathMutable" + | "dblint/splinter/insecureQueueExposedInApi" + | "dblint/splinter/materializedViewInApi" + | "dblint/splinter/multiplePermissivePolicies" + | "dblint/splinter/noPrimaryKey" + | "dblint/splinter/policyExistsRlsDisabled" + | "dblint/splinter/rlsDisabledInPublic" + | "dblint/splinter/rlsEnabledNoPolicy" + | "dblint/splinter/rlsReferencesUserMetadata" + | "dblint/splinter/securityDefinerView" + | "dblint/splinter/tableBloat" + | "dblint/splinter/unindexedForeignKeys" + | "dblint/splinter/unknown" + | "dblint/splinter/unsupportedRegTypes" + | "dblint/splinter/unusedIndex" | "stdin" | "check" | "configuration" @@ -111,7 +133,9 @@ export type Category = | "dummy" | "lint" | "lint/performance" - | "lint/safety"; + | "lint/safety" + | "dblint" + | "dblint/splinter"; export interface Location { path?: Resource_for_String; sourceCode?: string; diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index 17d35503a..733411d43 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -128,15 +128,6 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { &format!("\n{}\n ", splinter_entries), )?; - // Replace content between splinter groups markers - let groups_start = "// splinter groups start"; - let groups_end = "// splinter groups end"; - - let groups_content = "\n \"dblint\",\n \"dblint/splinter\",\n "; - - let new_content = - replace_between_markers(&new_content, groups_start, groups_end, groups_content)?; - fs2::write(categories_path, new_content)?; Ok(()) From 964de40a908807aeb9f2a2d7da26ea96897484ab Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 20:19:35 +0100 Subject: [PATCH 04/17] progress --- .../backend-jsonrpc/src/workspace.ts | 4 +--- packages/@postgrestools/backend-jsonrpc/src/workspace.ts | 4 +--- 2 files changed, 2 insertions(+), 6 deletions(-) diff --git a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts index 7cebb9bda..1f9f9d65d 100644 --- a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts @@ -133,9 +133,7 @@ export type Category = | "dummy" | "lint" | "lint/performance" - | "lint/safety" - | "dblint" - | "dblint/splinter"; + | "lint/safety"; export interface Location { path?: Resource_for_String; sourceCode?: string; diff --git a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts index 7cebb9bda..1f9f9d65d 100644 --- a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts @@ -133,9 +133,7 @@ export type Category = | "dummy" | "lint" | "lint/performance" - | "lint/safety" - | "dblint" - | "dblint/splinter"; + | "lint/safety"; export interface Location { path?: Resource_for_String; sourceCode?: string; From 09c5718c54314771fc06fd7c109bfa11aa44d54d Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 20:22:11 +0100 Subject: [PATCH 05/17] progress --- xtask/codegen/src/generate_splinter.rs | 13 ++++++------- 1 file changed, 6 insertions(+), 7 deletions(-) diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index 733411d43..fbef5e0d2 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -8,7 +8,7 @@ use xtask::{glue::fs2, project_root}; pub fn generate_splinter() -> Result<()> { let sql_path = project_root().join("crates/pgls_splinter/vendor/splinter.sql"); let sql_content = fs::read_to_string(&sql_path) - .with_context(|| format!("Failed to read SQL file at {:?}", sql_path))?; + .with_context(|| format!("Failed to read SQL file at {sql_path:?}"))?; let rules = extract_rules_from_sql(&sql_content)?; @@ -40,9 +40,8 @@ fn extract_rules_from_sql(content: &str) -> Result> { } } - let url = remediation_url.with_context(|| { - format!("Failed to find remediation URL for rule '{}'", name) - })?; + let url = remediation_url + .with_context(|| format!("Failed to find remediation URL for rule '{name}'"))?; rules.insert( name.clone(), @@ -125,7 +124,7 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { &content, rules_start, rules_end, - &format!("\n{}\n ", splinter_entries), + &format!("\n{splinter_entries}\n "), )?; fs2::write(categories_path, new_content)?; @@ -142,11 +141,11 @@ fn replace_between_markers( ) -> Result { let start_pos = content .find(start_marker) - .with_context(|| format!("Could not find '{}' marker", start_marker))?; + .with_context(|| format!("Could not find '{start_marker}' marker"))?; let end_pos = content .find(end_marker) - .with_context(|| format!("Could not find '{}' marker", end_marker))?; + .with_context(|| format!("Could not find '{end_marker}' marker"))?; let mut result = String::new(); result.push_str(&content[..start_pos + start_marker.len()]); From bc721f72f7848051a58047771e823b221e52de4d Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 20:52:06 +0100 Subject: [PATCH 06/17] fix: test --- crates/pgls_splinter/tests/diagnostics.rs | 35 +++++++++-------------- 1 file changed, 14 insertions(+), 21 deletions(-) diff --git a/crates/pgls_splinter/tests/diagnostics.rs b/crates/pgls_splinter/tests/diagnostics.rs index 730c3adee..a1fada7e1 100644 --- a/crates/pgls_splinter/tests/diagnostics.rs +++ b/crates/pgls_splinter/tests/diagnostics.rs @@ -1,6 +1,6 @@ use pgls_console::fmt::{Formatter, HTML}; use pgls_diagnostics::{Diagnostic, LogCategory, Visit}; -use pgls_splinter::{SplinterParams, run_splinter}; +use pgls_splinter::{run_splinter, SplinterParams}; use sqlx::PgPool; use std::fmt::Write; use std::io; @@ -52,26 +52,19 @@ struct TestSetup<'a> { impl TestSetup<'_> { async fn test(self) { // Create Supabase-specific roles that splinter expects - sqlx::raw_sql( - r#" - do $$ - begin - if not exists (select from pg_roles where rolname = 'anon') then - create role anon nologin; - end if; - if not exists (select from pg_roles where rolname = 'authenticated') then - create role authenticated nologin; - end if; - if not exists (select from pg_roles where rolname = 'service_role') then - create role service_role nologin; - end if; - end - $$; - "#, - ) - .execute(self.test_db) - .await - .expect("Failed to create Supabase roles"); + for role in ["anon", "authenticated", "service_role"] { + let result = sqlx::query(&format!("CREATE ROLE {role} NOLOGIN")) + .execute(self.test_db) + .await; + + // Ignore duplicate role errors + if let Err(sqlx::Error::Database(db_err)) = &result { + let code = db_err.code(); + if code.as_deref() != Some("23505") && code.as_deref() != Some("42710") { + result.expect("Failed to create Supabase roles"); + } + } + } // Run setup SQL sqlx::raw_sql(self.setup) From 92005d852c7c9b299860fdd9ec4aaa799d6808c1 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 21:32:48 +0100 Subject: [PATCH 07/17] refactor: use categories as group --- .../src/categories.rs | 44 ++++----- crates/pgls_splinter/src/convert.rs | 89 +++++++++++++------ .../tests/snapshots/multiple_issues.snap | 4 +- .../tests/snapshots/no_primary_key.snap | 2 +- .../snapshots/policy_exists_rls_disabled.snap | 2 +- .../snapshots/unindexed_foreign_key.snap | 2 +- xtask/codegen/src/generate_splinter.rs | 89 ++++++++++++++++--- 7 files changed, 167 insertions(+), 65 deletions(-) diff --git a/crates/pgls_diagnostics_categories/src/categories.rs b/crates/pgls_diagnostics_categories/src/categories.rs index 7cea0ea7a..d9a2b3de1 100644 --- a/crates/pgls_diagnostics_categories/src/categories.rs +++ b/crates/pgls_diagnostics_categories/src/categories.rs @@ -48,28 +48,28 @@ define_categories! { "lint/safety/transactionNesting": "https://pg-language-server.com/latest/rules/transaction-nesting", // end lint rules // splinter rules start - "dblint/splinter/authRlsInitplan": "https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan", - "dblint/splinter/authUsersExposed": "https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed", - "dblint/splinter/duplicateIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index", - "dblint/splinter/extensionInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public", - "dblint/splinter/extensionVersionsOutdated": "https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated", - "dblint/splinter/fkeyToAuthUnique": "https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique", - "dblint/splinter/foreignTableInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api", - "dblint/splinter/functionSearchPathMutable": "https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable", - "dblint/splinter/insecureQueueExposedInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api", - "dblint/splinter/materializedViewInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api", - "dblint/splinter/multiplePermissivePolicies": "https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies", - "dblint/splinter/noPrimaryKey": "https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key", - "dblint/splinter/policyExistsRlsDisabled": "https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled", - "dblint/splinter/rlsDisabledInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public", - "dblint/splinter/rlsEnabledNoPolicy": "https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy", - "dblint/splinter/rlsReferencesUserMetadata": "https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata", - "dblint/splinter/securityDefinerView": "https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view", - "dblint/splinter/tableBloat": "https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat", - "dblint/splinter/unindexedForeignKeys": "https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys", - "dblint/splinter/unknown": "https://pg-language-server.com/latest", - "dblint/splinter/unsupportedRegTypes": "https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types", - "dblint/splinter/unusedIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index", + "splinter/performance/authRlsInitplan": "https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan", + "splinter/performance/duplicateIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index", + "splinter/performance/multiplePermissivePolicies": "https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies", + "splinter/performance/noPrimaryKey": "https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key", + "splinter/performance/tableBloat": "https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat", + "splinter/performance/unindexedForeignKeys": "https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys", + "splinter/performance/unusedIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index", + "splinter/security/authUsersExposed": "https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed", + "splinter/security/extensionInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public", + "splinter/security/extensionVersionsOutdated": "https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated", + "splinter/security/fkeyToAuthUnique": "https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique", + "splinter/security/foreignTableInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api", + "splinter/security/functionSearchPathMutable": "https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable", + "splinter/security/insecureQueueExposedInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api", + "splinter/security/materializedViewInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api", + "splinter/security/policyExistsRlsDisabled": "https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled", + "splinter/security/rlsDisabledInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public", + "splinter/security/rlsEnabledNoPolicy": "https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy", + "splinter/security/rlsReferencesUserMetadata": "https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata", + "splinter/security/securityDefinerView": "https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view", + "splinter/security/unsupportedRegTypes": "https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types", + "splinter/unknown/unknown": "https://pg-language-server.com/latest", // splinter rules end ; // General categories diff --git a/crates/pgls_splinter/src/convert.rs b/crates/pgls_splinter/src/convert.rs index a9d53cfdf..95a912e5d 100644 --- a/crates/pgls_splinter/src/convert.rs +++ b/crates/pgls_splinter/src/convert.rs @@ -1,4 +1,4 @@ -use pgls_diagnostics::{Category, Severity, category}; +use pgls_diagnostics::{category, Category, Severity}; use serde_json::Value; use crate::{SplinterAdvices, SplinterDiagnostic, SplinterQueryResult}; @@ -11,8 +11,15 @@ impl From for SplinterDiagnostic { let (schema, object_name, object_type, additional_metadata) = extract_metadata_fields(&result.metadata); + // for now, we just take the first category as the group + let group = result + .categories + .first() + .map(|s| s.to_lowercase()) + .unwrap_or_else(|| "unknown".to_string()); + SplinterDiagnostic { - category: rule_name_to_category(&result.name), + category: rule_name_to_category(&result.name, &group), message: result.detail.into(), severity, advices: SplinterAdvices { @@ -37,32 +44,60 @@ fn parse_severity(level: &str) -> Severity { } } -/// Convert rule name to a Category +/// Convert rule name and group to a Category /// Note: Rule names use snake_case, but categories use camelCase -fn rule_name_to_category(name: &str) -> &'static Category { - match name { - "unindexed_foreign_keys" => category!("dblint/splinter/unindexedForeignKeys"), - "auth_users_exposed" => category!("dblint/splinter/authUsersExposed"), - "auth_rls_initplan" => category!("dblint/splinter/authRlsInitplan"), - "no_primary_key" => category!("dblint/splinter/noPrimaryKey"), - "unused_index" => category!("dblint/splinter/unusedIndex"), - "multiple_permissive_policies" => category!("dblint/splinter/multiplePermissivePolicies"), - "policy_exists_rls_disabled" => category!("dblint/splinter/policyExistsRlsDisabled"), - "rls_enabled_no_policy" => category!("dblint/splinter/rlsEnabledNoPolicy"), - "duplicate_index" => category!("dblint/splinter/duplicateIndex"), - "security_definer_view" => category!("dblint/splinter/securityDefinerView"), - "function_search_path_mutable" => category!("dblint/splinter/functionSearchPathMutable"), - "rls_disabled_in_public" => category!("dblint/splinter/rlsDisabledInPublic"), - "extension_in_public" => category!("dblint/splinter/extensionInPublic"), - "rls_references_user_metadata" => category!("dblint/splinter/rlsReferencesUserMetadata"), - "materialized_view_in_api" => category!("dblint/splinter/materializedViewInApi"), - "foreign_table_in_api" => category!("dblint/splinter/foreignTableInApi"), - "unsupported_reg_types" => category!("dblint/splinter/unsupportedRegTypes"), - "insecure_queue_exposed_in_api" => category!("dblint/splinter/insecureQueueExposedInApi"), - "table_bloat" => category!("dblint/splinter/tableBloat"), - "fkey_to_auth_unique" => category!("dblint/splinter/fkeyToAuthUnique"), - "extension_versions_outdated" => category!("dblint/splinter/extensionVersionsOutdated"), - _ => category!("dblint/splinter/unknown"), +fn rule_name_to_category(name: &str, group: &str) -> &'static Category { + match (group, name) { + ("performance", "unindexed_foreign_keys") => { + category!("splinter/performance/unindexedForeignKeys") + } + ("performance", "auth_rls_initplan") => { + category!("splinter/performance/authRlsInitplan") + } + ("performance", "no_primary_key") => category!("splinter/performance/noPrimaryKey"), + ("performance", "unused_index") => category!("splinter/performance/unusedIndex"), + ("performance", "duplicate_index") => category!("splinter/performance/duplicateIndex"), + ("performance", "table_bloat") => category!("splinter/performance/tableBloat"), + ("performance", "multiple_permissive_policies") => { + category!("splinter/performance/multiplePermissivePolicies") + } + ("security", "auth_users_exposed") => category!("splinter/security/authUsersExposed"), + ("security", "extension_versions_outdated") => { + category!("splinter/security/extensionVersionsOutdated") + } + ("security", "policy_exists_rls_disabled") => { + category!("splinter/security/policyExistsRlsDisabled") + } + ("security", "rls_enabled_no_policy") => { + category!("splinter/security/rlsEnabledNoPolicy") + } + ("security", "security_definer_view") => { + category!("splinter/security/securityDefinerView") + } + ("security", "function_search_path_mutable") => { + category!("splinter/security/functionSearchPathMutable") + } + ("security", "rls_disabled_in_public") => { + category!("splinter/security/rlsDisabledInPublic") + } + ("security", "extension_in_public") => category!("splinter/security/extensionInPublic"), + ("security", "rls_references_user_metadata") => { + category!("splinter/security/rlsReferencesUserMetadata") + } + ("security", "materialized_view_in_api") => { + category!("splinter/security/materializedViewInApi") + } + ("security", "foreign_table_in_api") => { + category!("splinter/security/foreignTableInApi") + } + ("security", "unsupported_reg_types") => { + category!("splinter/security/unsupportedRegTypes") + } + ("security", "insecure_queue_exposed_in_api") => { + category!("splinter/security/insecureQueueExposedInApi") + } + ("security", "fkey_to_auth_unique") => category!("splinter/security/fkeyToAuthUnique"), + _ => category!("splinter/unknown/unknown"), } } diff --git a/crates/pgls_splinter/tests/snapshots/multiple_issues.snap b/crates/pgls_splinter/tests/snapshots/multiple_issues.snap index b214c2417..7cce55230 100644 --- a/crates/pgls_splinter/tests/snapshots/multiple_issues.snap +++ b/crates/pgls_splinter/tests/snapshots/multiple_issues.snap @@ -3,7 +3,7 @@ source: crates/pgls_splinter/tests/diagnostics.rs expression: content snapshot_kind: text --- -Category: dblint/splinter/unindexedForeignKeys +Category: splinter/performance/unindexedForeignKeys Severity: Information Message: Table \`public.child_table\` has a foreign key \`child_table_parent_id_fkey\` without a covering index. This can lead to suboptimal query performance. Advices: @@ -14,7 +14,7 @@ Identifies foreign key constraints without a covering index, which can impact da --- -Category: dblint/splinter/noPrimaryKey +Category: splinter/performance/noPrimaryKey Severity: Information Message: Table \`public.no_pk_table\` does not have a primary key Advices: diff --git a/crates/pgls_splinter/tests/snapshots/no_primary_key.snap b/crates/pgls_splinter/tests/snapshots/no_primary_key.snap index 2f9dbf66e..d6bc383ee 100644 --- a/crates/pgls_splinter/tests/snapshots/no_primary_key.snap +++ b/crates/pgls_splinter/tests/snapshots/no_primary_key.snap @@ -3,7 +3,7 @@ source: crates/pgls_splinter/tests/diagnostics.rs expression: content snapshot_kind: text --- -Category: dblint/splinter/noPrimaryKey +Category: splinter/performance/noPrimaryKey Severity: Information Message: Table \`public.articles\` does not have a primary key Advices: diff --git a/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap b/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap index f7f57da57..2603ed7e0 100644 --- a/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap +++ b/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap @@ -3,7 +3,7 @@ source: crates/pgls_splinter/tests/diagnostics.rs expression: content snapshot_kind: text --- -Category: dblint/splinter/policyExistsRlsDisabled +Category: splinter/security/policyExistsRlsDisabled Severity: Error Message: Table \`public.documents\` has RLS policies but RLS is not enabled on the table. Policies include {documents_policy}. Advices: diff --git a/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap b/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap index e4f9b5fe9..ef31777b9 100644 --- a/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap +++ b/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap @@ -3,7 +3,7 @@ source: crates/pgls_splinter/tests/diagnostics.rs expression: content snapshot_kind: text --- -Category: dblint/splinter/unindexedForeignKeys +Category: splinter/performance/unindexedForeignKeys Severity: Information Message: Table \`public.posts\` has a foreign key \`posts_user_id_fkey\` without a covering index. This can lead to suboptimal query performance. Advices: diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index fbef5e0d2..caa45379a 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -30,12 +30,24 @@ fn extract_rules_from_sql(content: &str) -> Result> { // Look for pattern: 'rule_name' as "name!", if line.contains(" as \"name!\"") { if let Some(name) = extract_string_literal(line) { - // Look ahead for remediation URL + // Look ahead for categories and remediation URL + let mut categories = None; let mut remediation_url = None; + for j in i..std::cmp::min(i + 30, lines.len()) { let next_line = lines[j].trim(); + + // Extract categories from pattern: array['CATEGORY'] as "categories!", + if next_line.contains(" as \"categories!\"") { + categories = extract_categories(next_line); + } + if next_line.contains(" as \"remediation!\"") { remediation_url = extract_string_literal(next_line); + } + + // Stop once we have both + if categories.is_some() && remediation_url.is_some() { break; } } @@ -43,11 +55,15 @@ fn extract_rules_from_sql(content: &str) -> Result> { let url = remediation_url .with_context(|| format!("Failed to find remediation URL for rule '{name}'"))?; + let cats = categories + .with_context(|| format!("Failed to find categories for rule '{name}'"))?; + rules.insert( name.clone(), RuleInfo { snake_case: name.clone(), camel_case: snake_to_camel_case(&name), + categories: cats, url, }, ); @@ -63,6 +79,7 @@ fn extract_rules_from_sql(content: &str) -> Result> { RuleInfo { snake_case: "unknown".to_string(), camel_case: "unknown".to_string(), + categories: vec!["UNKNOWN".to_string()], url: "https://pg-language-server.com/latest".to_string(), }, ); @@ -83,6 +100,40 @@ fn extract_string_literal(line: &str) -> Option { None } +/// Extract categories from a line like "array['CATEGORY'] as "categories!"," +fn extract_categories(line: &str) -> Option> { + let trimmed = line.trim(); + + // Look for array['...'] + if let Some(start) = trimmed.find("array[") { + if let Some(end) = trimmed[start..].find(']') { + let array_content = &trimmed[start + 6..start + end]; + + // Extract all string literals within the array + let categories: Vec = array_content + .split(',') + .filter_map(|s| { + let s = s.trim(); + if let Some(start_quote) = s.find('\'') { + if let Some(end_quote) = s[start_quote + 1..].find('\'') { + return Some( + s[start_quote + 1..start_quote + 1 + end_quote].to_string(), + ); + } + } + None + }) + .collect(); + + if !categories.is_empty() { + return Some(categories); + } + } + } + + None +} + /// Convert snake_case to camelCase fn snake_to_camel_case(s: &str) -> String { Case::Camel.convert(s) @@ -92,6 +143,7 @@ struct RuleInfo { #[allow(dead_code)] snake_case: String, camel_case: String, + categories: Vec, url: String, } @@ -102,19 +154,34 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { let content = fs2::read_to_string(&categories_path)?; - // Generate splinter rule entries - let mut splinter_rules: Vec = rules + // Generate splinter rule entries grouped by category + let mut splinter_rules: Vec<(String, String)> = rules .values() - .map(|rule| { - format!( - " \"dblint/splinter/{}\": \"{}\",", - rule.camel_case, rule.url - ) + .flat_map(|rule| { + // For each rule, create entries for all its categories + // In practice, splinter rules have only one category + rule.categories.iter().map(|category| { + let group = category.to_lowercase(); + ( + group.clone(), + format!( + " \"splinter/{}/{}\": \"{}\",", + group, rule.camel_case, rule.url + ), + ) + }) }) - .collect(); + .collect::>(); + + // Sort by group, then by entry + splinter_rules.sort_by(|a, b| a.0.cmp(&b.0).then_with(|| a.1.cmp(&b.1))); - splinter_rules.sort(); - let splinter_entries = splinter_rules.join("\n"); + // Extract just the formatted strings + let splinter_entries: String = splinter_rules + .iter() + .map(|(_, entry)| entry.as_str()) + .collect::>() + .join("\n"); // Replace content between splinter rules markers let rules_start = "// splinter rules start"; From 1dcb8d79988e3828f13ee9dbf23f552ee157a830 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 21:35:12 +0100 Subject: [PATCH 08/17] refactor: use categories as group --- .../backend-jsonrpc/src/workspace.ts | 44 +++++++++---------- .../backend-jsonrpc/src/workspace.ts | 44 +++++++++---------- 2 files changed, 44 insertions(+), 44 deletions(-) diff --git a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts index 1f9f9d65d..cd80ca745 100644 --- a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts @@ -95,28 +95,28 @@ export type Category = | "lint/safety/requireConcurrentIndexDeletion" | "lint/safety/runningStatementWhileHoldingAccessExclusive" | "lint/safety/transactionNesting" - | "dblint/splinter/authRlsInitplan" - | "dblint/splinter/authUsersExposed" - | "dblint/splinter/duplicateIndex" - | "dblint/splinter/extensionInPublic" - | "dblint/splinter/extensionVersionsOutdated" - | "dblint/splinter/fkeyToAuthUnique" - | "dblint/splinter/foreignTableInApi" - | "dblint/splinter/functionSearchPathMutable" - | "dblint/splinter/insecureQueueExposedInApi" - | "dblint/splinter/materializedViewInApi" - | "dblint/splinter/multiplePermissivePolicies" - | "dblint/splinter/noPrimaryKey" - | "dblint/splinter/policyExistsRlsDisabled" - | "dblint/splinter/rlsDisabledInPublic" - | "dblint/splinter/rlsEnabledNoPolicy" - | "dblint/splinter/rlsReferencesUserMetadata" - | "dblint/splinter/securityDefinerView" - | "dblint/splinter/tableBloat" - | "dblint/splinter/unindexedForeignKeys" - | "dblint/splinter/unknown" - | "dblint/splinter/unsupportedRegTypes" - | "dblint/splinter/unusedIndex" + | "splinter/performance/authRlsInitplan" + | "splinter/performance/duplicateIndex" + | "splinter/performance/multiplePermissivePolicies" + | "splinter/performance/noPrimaryKey" + | "splinter/performance/tableBloat" + | "splinter/performance/unindexedForeignKeys" + | "splinter/performance/unusedIndex" + | "splinter/security/authUsersExposed" + | "splinter/security/extensionInPublic" + | "splinter/security/extensionVersionsOutdated" + | "splinter/security/fkeyToAuthUnique" + | "splinter/security/foreignTableInApi" + | "splinter/security/functionSearchPathMutable" + | "splinter/security/insecureQueueExposedInApi" + | "splinter/security/materializedViewInApi" + | "splinter/security/policyExistsRlsDisabled" + | "splinter/security/rlsDisabledInPublic" + | "splinter/security/rlsEnabledNoPolicy" + | "splinter/security/rlsReferencesUserMetadata" + | "splinter/security/securityDefinerView" + | "splinter/security/unsupportedRegTypes" + | "splinter/unknown/unknown" | "stdin" | "check" | "configuration" diff --git a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts index 1f9f9d65d..cd80ca745 100644 --- a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts @@ -95,28 +95,28 @@ export type Category = | "lint/safety/requireConcurrentIndexDeletion" | "lint/safety/runningStatementWhileHoldingAccessExclusive" | "lint/safety/transactionNesting" - | "dblint/splinter/authRlsInitplan" - | "dblint/splinter/authUsersExposed" - | "dblint/splinter/duplicateIndex" - | "dblint/splinter/extensionInPublic" - | "dblint/splinter/extensionVersionsOutdated" - | "dblint/splinter/fkeyToAuthUnique" - | "dblint/splinter/foreignTableInApi" - | "dblint/splinter/functionSearchPathMutable" - | "dblint/splinter/insecureQueueExposedInApi" - | "dblint/splinter/materializedViewInApi" - | "dblint/splinter/multiplePermissivePolicies" - | "dblint/splinter/noPrimaryKey" - | "dblint/splinter/policyExistsRlsDisabled" - | "dblint/splinter/rlsDisabledInPublic" - | "dblint/splinter/rlsEnabledNoPolicy" - | "dblint/splinter/rlsReferencesUserMetadata" - | "dblint/splinter/securityDefinerView" - | "dblint/splinter/tableBloat" - | "dblint/splinter/unindexedForeignKeys" - | "dblint/splinter/unknown" - | "dblint/splinter/unsupportedRegTypes" - | "dblint/splinter/unusedIndex" + | "splinter/performance/authRlsInitplan" + | "splinter/performance/duplicateIndex" + | "splinter/performance/multiplePermissivePolicies" + | "splinter/performance/noPrimaryKey" + | "splinter/performance/tableBloat" + | "splinter/performance/unindexedForeignKeys" + | "splinter/performance/unusedIndex" + | "splinter/security/authUsersExposed" + | "splinter/security/extensionInPublic" + | "splinter/security/extensionVersionsOutdated" + | "splinter/security/fkeyToAuthUnique" + | "splinter/security/foreignTableInApi" + | "splinter/security/functionSearchPathMutable" + | "splinter/security/insecureQueueExposedInApi" + | "splinter/security/materializedViewInApi" + | "splinter/security/policyExistsRlsDisabled" + | "splinter/security/rlsDisabledInPublic" + | "splinter/security/rlsEnabledNoPolicy" + | "splinter/security/rlsReferencesUserMetadata" + | "splinter/security/securityDefinerView" + | "splinter/security/unsupportedRegTypes" + | "splinter/unknown/unknown" | "stdin" | "check" | "configuration" From 60fd54ef2db9525708ecf84544a8de8b822031f1 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 21:46:30 +0100 Subject: [PATCH 09/17] fix: format --- crates/pgls_splinter/src/convert.rs | 2 +- crates/pgls_splinter/tests/diagnostics.rs | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/crates/pgls_splinter/src/convert.rs b/crates/pgls_splinter/src/convert.rs index 95a912e5d..dc445deee 100644 --- a/crates/pgls_splinter/src/convert.rs +++ b/crates/pgls_splinter/src/convert.rs @@ -1,4 +1,4 @@ -use pgls_diagnostics::{category, Category, Severity}; +use pgls_diagnostics::{Category, Severity, category}; use serde_json::Value; use crate::{SplinterAdvices, SplinterDiagnostic, SplinterQueryResult}; diff --git a/crates/pgls_splinter/tests/diagnostics.rs b/crates/pgls_splinter/tests/diagnostics.rs index a1fada7e1..576b69952 100644 --- a/crates/pgls_splinter/tests/diagnostics.rs +++ b/crates/pgls_splinter/tests/diagnostics.rs @@ -1,6 +1,6 @@ use pgls_console::fmt::{Formatter, HTML}; use pgls_diagnostics::{Diagnostic, LogCategory, Visit}; -use pgls_splinter::{run_splinter, SplinterParams}; +use pgls_splinter::{SplinterParams, run_splinter}; use sqlx::PgPool; use std::fmt::Write; use std::io; From e7a2dd54774326a586f653bcb7f52aaea04217fd Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 23:18:44 +0100 Subject: [PATCH 10/17] fix: unknown url and add groups to categories --- .../src/categories.rs | 8 ++++- xtask/codegen/src/generate_splinter.rs | 31 +++++++++++++++++-- 2 files changed, 35 insertions(+), 4 deletions(-) diff --git a/crates/pgls_diagnostics_categories/src/categories.rs b/crates/pgls_diagnostics_categories/src/categories.rs index d9a2b3de1..ba0e4c65d 100644 --- a/crates/pgls_diagnostics_categories/src/categories.rs +++ b/crates/pgls_diagnostics_categories/src/categories.rs @@ -93,5 +93,11 @@ define_categories! { "lint/performance", "lint/safety", // Lint groups end -} + // Splinter groups start + "splinter", + "splinter/performance", + "splinter/security", + "splinter/unknown", + // Splinter groups end +} diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index caa45379a..1d0a48e8a 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -152,7 +152,7 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { let categories_path = project_root().join("crates/pgls_diagnostics_categories/src/categories.rs"); - let content = fs2::read_to_string(&categories_path)?; + let mut content = fs2::read_to_string(&categories_path)?; // Generate splinter rule entries grouped by category let mut splinter_rules: Vec<(String, String)> = rules @@ -187,14 +187,39 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { let rules_start = "// splinter rules start"; let rules_end = "// splinter rules end"; - let new_content = replace_between_markers( + content = replace_between_markers( &content, rules_start, rules_end, &format!("\n{splinter_entries}\n "), )?; - fs2::write(categories_path, new_content)?; + // Generate splinter group entries + let mut groups: Vec = splinter_rules + .iter() + .map(|(group, _)| group.clone()) + .collect(); + groups.sort(); + groups.dedup(); + + let mut group_entries = vec![" \"splinter\",".to_string()]; + for group in groups { + group_entries.push(format!(" \"splinter/{}\",", group)); + } + let groups_content = group_entries.join("\n"); + + // Replace content between splinter groups markers + let groups_start = "// Splinter groups start"; + let groups_end = "// Splinter groups end"; + + content = replace_between_markers( + &content, + groups_start, + groups_end, + &format!("\n{groups_content}\n "), + )?; + + fs2::write(categories_path, content)?; Ok(()) } From c35affc73a7fa6bc67e5e447de3040ccbdb0f007 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 23:19:41 +0100 Subject: [PATCH 11/17] fix: unknown url and add groups to categories --- .../backend-jsonrpc/src/workspace.ts | 6 +++++- packages/@postgrestools/backend-jsonrpc/src/workspace.ts | 6 +++++- 2 files changed, 10 insertions(+), 2 deletions(-) diff --git a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts index cd80ca745..cd8bf727b 100644 --- a/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgres-language-server/backend-jsonrpc/src/workspace.ts @@ -133,7 +133,11 @@ export type Category = | "dummy" | "lint" | "lint/performance" - | "lint/safety"; + | "lint/safety" + | "splinter" + | "splinter/performance" + | "splinter/security" + | "splinter/unknown"; export interface Location { path?: Resource_for_String; sourceCode?: string; diff --git a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts index cd80ca745..cd8bf727b 100644 --- a/packages/@postgrestools/backend-jsonrpc/src/workspace.ts +++ b/packages/@postgrestools/backend-jsonrpc/src/workspace.ts @@ -133,7 +133,11 @@ export type Category = | "dummy" | "lint" | "lint/performance" - | "lint/safety"; + | "lint/safety" + | "splinter" + | "splinter/performance" + | "splinter/security" + | "splinter/unknown"; export interface Location { path?: Resource_for_String; sourceCode?: string; From 81b811c57ff3303e6c62dbb7e7ea014079505d91 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Sat, 1 Nov 2025 23:46:13 +0100 Subject: [PATCH 12/17] fix: lint --- xtask/codegen/src/generate_splinter.rs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index 1d0a48e8a..627a7f8e6 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -204,7 +204,7 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { let mut group_entries = vec![" \"splinter\",".to_string()]; for group in groups { - group_entries.push(format!(" \"splinter/{}\",", group)); + group_entries.push(format!(" \"splinter/{group}\",")); } let groups_content = group_entries.join("\n"); From 79f4c9fe33f81973a5ae412df33c0482a7a7bccf Mon Sep 17 00:00:00 2001 From: psteinroe Date: Tue, 4 Nov 2025 07:55:16 +0100 Subject: [PATCH 13/17] refactor: split splinter rules --- ...5e4454b2c36eaf034657d5d2d95633fb85bdb.json | 74 +++ ...11046dc8b77d84c94314a0ed0716e5803df69.json | 74 +++ crates/pgls_splinter/build.rs | 89 ++- crates/pgls_splinter/src/convert.rs | 36 +- crates/pgls_splinter/src/lib.rs | 22 +- crates/pgls_splinter/src/query.rs | 26 +- crates/pgls_splinter/tests/diagnostics.rs | 25 +- crates/pgls_splinter/vendor/COMMIT_SHA.txt | 2 +- .../{splinter.sql => splinter_generic.sql} | 521 +----------------- .../vendor/splinter_supabase.sql | 516 +++++++++++++++++ xtask/codegen/src/generate_splinter.rs | 80 ++- 11 files changed, 897 insertions(+), 568 deletions(-) create mode 100644 crates/pgls_splinter/.sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json create mode 100644 crates/pgls_splinter/.sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json rename crates/pgls_splinter/vendor/{splinter.sql => splinter_generic.sql} (53%) create mode 100644 crates/pgls_splinter/vendor/splinter_supabase.sql diff --git a/crates/pgls_splinter/.sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json b/crates/pgls_splinter/.sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json new file mode 100644 index 000000000..459aa79a6 --- /dev/null +++ b/crates/pgls_splinter/.sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json @@ -0,0 +1,74 @@ +{ + "db_name": "PostgreSQL", + "query": "\n(\nwith foreign_keys as (\n select\n cl.relnamespace::regnamespace::text as schema_name,\n cl.relname as table_name,\n cl.oid as table_oid,\n ct.conname as fkey_name,\n ct.conkey as col_attnums\n from\n pg_catalog.pg_constraint ct\n join pg_catalog.pg_class cl -- fkey owning table\n on ct.conrelid = cl.oid\n left join pg_catalog.pg_depend d\n on d.objid = cl.oid\n and d.deptype = 'e'\n where\n ct.contype = 'f' -- foreign key constraints\n and d.objid is null -- exclude tables that are dependencies of extensions\n and cl.relnamespace::regnamespace::text not in (\n 'pg_catalog', 'information_schema', 'auth', 'storage', 'vault', 'extensions'\n )\n),\nindex_ as (\n select\n pi.indrelid as table_oid,\n indexrelid::regclass as index_,\n string_to_array(indkey::text, ' ')::smallint[] as col_attnums\n from\n pg_catalog.pg_index pi\n where\n indisvalid\n)\nselect\n 'unindexed_foreign_keys' as \"name!\",\n 'Unindexed foreign keys' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Identifies foreign key constraints without a covering index, which can impact database performance.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a foreign key \\`%s\\` without a covering index. This can lead to suboptimal query performance.',\n fk.schema_name,\n fk.table_name,\n fk.fkey_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys' as \"remediation!\",\n jsonb_build_object(\n 'schema', fk.schema_name,\n 'name', fk.table_name,\n 'type', 'table',\n 'fkey_name', fk.fkey_name,\n 'fkey_columns', fk.col_attnums\n ) as \"metadata!\",\n format('unindexed_foreign_keys_%s_%s_%s', fk.schema_name, fk.table_name, fk.fkey_name) as \"cache_key!\"\nfrom\n foreign_keys fk\n left join index_ idx\n on fk.table_oid = idx.table_oid\n and fk.col_attnums = idx.col_attnums[1:array_length(fk.col_attnums, 1)]\n left join pg_catalog.pg_depend dep\n on idx.table_oid = dep.objid\n and dep.deptype = 'e'\nwhere\n idx.index_ is null\n and fk.schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\norder by\n fk.schema_name,\n fk.table_name,\n fk.fkey_name)\nunion all\n\n(\nselect\n 'no_primary_key' as \"name!\",\n 'No Primary Key' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` does not have a primary key',\n pgns.nspname,\n pgc.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key' as \"remediation!\",\n jsonb_build_object(\n 'schema', pgns.nspname,\n 'name', pgc.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'no_primary_key_%s_%s',\n pgns.nspname,\n pgc.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class pgc\n join pg_catalog.pg_namespace pgns\n on pgns.oid = pgc.relnamespace\n left join pg_catalog.pg_index pgi\n on pgi.indrelid = pgc.oid\n left join pg_catalog.pg_depend dep\n on pgc.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n pgc.relkind = 'r' -- regular tables\n and pgns.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n pgc.oid,\n pgns.nspname,\n pgc.relname\nhaving\n max(coalesce(pgi.indisprimary, false)::int) = 0)\nunion all\n\n(\nselect\n 'unused_index' as \"name!\",\n 'Unused Index' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if an index has never been used and may be a candidate for removal.' as \"description!\",\n format(\n 'Index \\`%s\\` on table \\`%s.%s\\` has not been used',\n psui.indexrelname,\n psui.schemaname,\n psui.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', psui.schemaname,\n 'name', psui.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unused_index_%s_%s_%s',\n psui.schemaname,\n psui.relname,\n psui.indexrelname\n ) as \"cache_key!\"\n\nfrom\n pg_catalog.pg_stat_user_indexes psui\n join pg_catalog.pg_index pi\n on psui.indexrelid = pi.indexrelid\n left join pg_catalog.pg_depend dep\n on psui.relid = dep.objid\n and dep.deptype = 'e'\nwhere\n psui.idx_scan = 0\n and not pi.indisunique\n and not pi.indisprimary\n and dep.objid is null -- exclude tables owned by extensions\n and psui.schemaname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n\n(\nselect\n 'multiple_permissive_policies' as \"name!\",\n 'Multiple Permissive Policies' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if multiple permissive row level security policies are present on a table for the same \\`role\\` and \\`action\\` (e.g. insert). Multiple permissive policies are suboptimal for performance as each policy must be executed for every relevant query.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has multiple permissive policies for role \\`%s\\` for action \\`%s\\`. Policies include \\`%s\\`',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'multiple_permissive_policies_%s_%s_%s_%s',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_roles r\n on p.polroles @> array[r.oid]\n or p.polroles = array[0::oid]\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e',\n lateral (\n select x.cmd\n from unnest((\n select\n case p.polcmd\n when 'r' then array['SELECT']\n when 'a' then array['INSERT']\n when 'w' then array['UPDATE']\n when 'd' then array['DELETE']\n when '*' then array['SELECT', 'INSERT', 'UPDATE', 'DELETE']\n else array['ERROR']\n end as actions\n )) x(cmd)\n ) act(cmd)\nwhere\n c.relkind = 'r' -- regular tables\n and p.polpermissive -- policy is permissive\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and r.rolname not like 'pg_%'\n and r.rolname not like 'supabase%admin'\n and not r.rolbypassrls\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\nhaving\n count(1) > 1)\nunion all\n\n(\nselect\n 'policy_exists_rls_disabled' as \"name!\",\n 'Policy Exists RLS Disabled' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) policies have been created, but RLS has not been enabled for the underlying table.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS policies but RLS is not enabled on the table. Policies include %s.',\n n.nspname,\n c.relname,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'policy_exists_rls_disabled_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is disabled\n and not c.relrowsecurity\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n\n(\nselect\n 'rls_enabled_no_policy' as \"name!\",\n 'RLS Enabled No Policy' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has been enabled on a table but no RLS policies have been created.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS enabled, but no policies exist',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_enabled_no_policy_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n left join pg_catalog.pg_policy p\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is enabled\n and c.relrowsecurity\n and p.polname is null\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n\n(\nselect\n 'duplicate_index' as \"name!\",\n 'Duplicate Index' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects cases where two ore more identical indexes exist.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has identical indexes %s. Drop all except one of them',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', case\n when c.relkind = 'r' then 'table'\n when c.relkind = 'm' then 'materialized view'\n else 'ERROR'\n end,\n 'indexes', array_agg(pi.indexname order by pi.indexname)\n ) as \"metadata!\",\n format(\n 'duplicate_index_%s_%s_%s',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_indexes pi\n join pg_catalog.pg_namespace n\n on n.nspname = pi.schemaname\n join pg_catalog.pg_class c\n on pi.tablename = c.relname\n and n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind in ('r', 'm') -- tables and materialized views\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relkind,\n c.relname,\n replace(pi.indexdef, pi.indexname, '')\nhaving\n count(*) > 1)\nunion all\n\n(\nselect\n 'function_search_path_mutable' as \"name!\",\n 'Function Search Path Mutable' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects functions where the search_path parameter is not set.' as \"description!\",\n format(\n 'Function \\`%s.%s\\` has a role mutable search_path',\n n.nspname,\n p.proname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', p.proname,\n 'type', 'function'\n ) as \"metadata!\",\n format(\n 'function_search_path_mutable_%s_%s_%s',\n n.nspname,\n p.proname,\n md5(p.prosrc) -- required when function is polymorphic\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_proc p\n join pg_catalog.pg_namespace n\n on p.pronamespace = n.oid\n left join pg_catalog.pg_depend dep\n on p.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude functions owned by extensions\n -- Search path not set\n and not exists (\n select 1\n from unnest(coalesce(p.proconfig, '{}')) as config\n where config like 'search_path=%'\n ))\nunion all\n\n(\nselect\n 'extension_in_public' as \"name!\",\n 'Extension in Public' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions installed in the \\`public\\` schema.' as \"description!\",\n format(\n 'Extension \\`%s\\` is installed in the public schema. Move it to another schema.',\n pe.extname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', pe.extnamespace::regnamespace,\n 'name', pe.extname,\n 'type', 'extension'\n ) as \"metadata!\",\n format(\n 'extension_in_public_%s',\n pe.extname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_extension pe\nwhere\n -- plpgsql is installed by default in public and outside user control\n -- confirmed safe\n pe.extname not in ('plpgsql')\n -- Scoping this to public is not optimal. Ideally we would use the postgres\n -- search path. That currently isn't available via SQL. In other lints\n -- we have used has_schema_privilege('anon', 'extensions', 'USAGE') but that\n -- is not appropriate here as it would evaluate true for the extensions schema\n and pe.extnamespace::regnamespace::text = 'public')\nunion all\n\n(\nselect\n 'unsupported_reg_types' as \"name!\",\n 'Unsupported reg types' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Identifies columns using unsupported reg* types outside pg_catalog schema, which prevents database upgrades using pg_upgrade.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a column \\`%s\\` with unsupported reg* type \\`%s\\`.',\n n.nspname,\n c.relname,\n a.attname,\n t.typname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'column', a.attname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unsupported_reg_types_%s_%s_%s',\n n.nspname,\n c.relname,\n a.attname\n ) AS cache_key\nfrom\n pg_catalog.pg_attribute a\n join pg_catalog.pg_class c\n on a.attrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_type t\n on a.atttypid = t.oid\n join pg_catalog.pg_namespace tn\n on t.typnamespace = tn.oid\nwhere\n tn.nspname = 'pg_catalog'\n and t.typname in ('regcollation', 'regconfig', 'regdictionary', 'regnamespace', 'regoper', 'regoperator', 'regproc', 'regprocedure')\n and n.nspname not in ('pg_catalog', 'information_schema', 'pgsodium'))\nunion all\n\n(\nwith constants as (\n select current_setting('block_size')::numeric as bs, 23 as hdr, 4 as ma\n),\n\nbloat_info as (\n select\n ma,\n bs,\n schemaname,\n tablename,\n (datawidth + (hdr + ma - (case when hdr % ma = 0 then ma else hdr % ma end)))::numeric as datahdr,\n (maxfracsum * (nullhdr + ma - (case when nullhdr % ma = 0 then ma else nullhdr % ma end))) as nullhdr2\n from (\n select\n schemaname,\n tablename,\n hdr,\n ma,\n bs,\n sum((1 - null_frac) * avg_width) as datawidth,\n max(null_frac) as maxfracsum,\n hdr + (\n select 1 + count(*) / 8\n from pg_stats s2\n where\n null_frac <> 0\n and s2.schemaname = s.schemaname\n and s2.tablename = s.tablename\n ) as nullhdr\n from pg_stats s, constants\n group by 1, 2, 3, 4, 5\n ) as foo\n),\n\ntable_bloat as (\n select\n schemaname,\n tablename,\n cc.relpages,\n bs,\n ceil((cc.reltuples * ((datahdr + ma -\n (case when datahdr % ma = 0 then ma else datahdr % ma end)) + nullhdr2 + 4)) / (bs - 20::float)) as otta\n from\n bloat_info\n join pg_class cc\n on cc.relname = bloat_info.tablename\n join pg_namespace nn\n on cc.relnamespace = nn.oid\n and nn.nspname = bloat_info.schemaname\n and nn.nspname <> 'information_schema'\n where\n cc.relkind = 'r'\n and cc.relam = (select oid from pg_am where amname = 'heap')\n),\n\nbloat_data as (\n select\n 'table' as type,\n schemaname,\n tablename as object_name,\n round(case when otta = 0 then 0.0 else table_bloat.relpages / otta::numeric end, 1) as bloat,\n case when relpages < otta then 0 else (bs * (table_bloat.relpages - otta)::bigint)::bigint end as raw_waste\n from\n table_bloat\n)\n\nselect\n 'table_bloat' as \"name!\",\n 'Table Bloat' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table has excess bloat and may benefit from maintenance operations like vacuum full or cluster.' as \"description!\",\n format(\n 'Table `%s`.`%s` has excessive bloat',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"detail!\",\n 'Consider running vacuum full (WARNING: incurs downtime) and tweaking autovacuum settings to reduce bloat.' as \"remediation!\",\n jsonb_build_object(\n 'schema', bloat_data.schemaname,\n 'name', bloat_data.object_name,\n 'type', bloat_data.type\n ) as \"metadata!\",\n format(\n 'table_bloat_%s_%s',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"cache_key!\"\nfrom\n bloat_data\nwhere\n bloat > 70.0\n and raw_waste > (20 * 1024 * 1024) -- filter for waste > 200 MB\norder by\n schemaname,\n object_name)\nunion all\n\n(\nselect\n 'extension_versions_outdated' as \"name!\",\n 'Extension Versions Outdated' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions that are not using the default (recommended) version.' as \"description!\",\n format(\n 'Extension `%s` is using version `%s` but version `%s` is available. Using outdated extension versions may expose the database to security vulnerabilities.',\n ext.name,\n ext.installed_version,\n ext.default_version\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated' as \"remediation!\",\n jsonb_build_object(\n 'extension_name', ext.name,\n 'installed_version', ext.installed_version,\n 'default_version', ext.default_version\n ) as \"metadata!\",\n format(\n 'extension_versions_outdated_%s_%s',\n ext.name,\n ext.installed_version\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_available_extensions ext\njoin\n -- ignore versions not in pg_available_extension_versions\n -- e.g. residue of pg_upgrade\n pg_catalog.pg_available_extension_versions extv\n on extv.name = ext.name and extv.installed\nwhere\n ext.installed_version is not null\n and ext.default_version is not null\n and ext.installed_version != ext.default_version\norder by\n ext.name)", + "describe": { + "columns": [ + { + "ordinal": 0, + "name": "name!", + "type_info": "Text" + }, + { + "ordinal": 1, + "name": "title!", + "type_info": "Text" + }, + { + "ordinal": 2, + "name": "level!", + "type_info": "Text" + }, + { + "ordinal": 3, + "name": "facing!", + "type_info": "Text" + }, + { + "ordinal": 4, + "name": "categories!", + "type_info": "TextArray" + }, + { + "ordinal": 5, + "name": "description!", + "type_info": "Text" + }, + { + "ordinal": 6, + "name": "detail!", + "type_info": "Text" + }, + { + "ordinal": 7, + "name": "remediation!", + "type_info": "Text" + }, + { + "ordinal": 8, + "name": "metadata!", + "type_info": "Jsonb" + }, + { + "ordinal": 9, + "name": "cache_key!", + "type_info": "Text" + } + ], + "parameters": { + "Left": [] + }, + "nullable": [ + null, + null, + null, + null, + null, + null, + null, + null, + null, + null + ] + }, + "hash": "02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb" +} diff --git a/crates/pgls_splinter/.sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json b/crates/pgls_splinter/.sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json new file mode 100644 index 000000000..27081d1c4 --- /dev/null +++ b/crates/pgls_splinter/.sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json @@ -0,0 +1,74 @@ +{ + "db_name": "PostgreSQL", + "query": "\n(\nselect\n 'auth_users_exposed' as \"name!\",\n 'Exposed Auth Users' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects if auth.users is exposed to anon or authenticated roles via a view or materialized view in schemas exposed to PostgREST, potentially compromising user data security.' as \"description!\",\n format(\n 'View/Materialized View \"%s\" in the public schema may expose \\`auth.users\\` data to anon or authenticated roles.',\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view',\n 'exposed_to', array_remove(array_agg(DISTINCT case when pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') then 'anon' when pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') then 'authenticated' end), null)\n ) as \"metadata!\",\n format('auth_users_exposed_%s_%s', n.nspname, c.relname) as \"cache_key!\"\nfrom\n -- Identify the oid for auth.users\n pg_catalog.pg_class auth_users_pg_class\n join pg_catalog.pg_namespace auth_users_pg_namespace\n on auth_users_pg_class.relnamespace = auth_users_pg_namespace.oid\n and auth_users_pg_class.relname = 'users'\n and auth_users_pg_namespace.nspname = 'auth'\n -- Depends on auth.users\n join pg_catalog.pg_depend d\n on d.refobjid = auth_users_pg_class.oid\n join pg_catalog.pg_rewrite r\n on r.oid = d.objid\n join pg_catalog.pg_class c\n on c.oid = r.ev_class\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n join pg_catalog.pg_class pg_class_auth_users\n on d.refobjid = pg_class_auth_users.oid\nwhere\n d.deptype = 'n'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n -- Exclude self\n and c.relname <> '0002_auth_users_exposed'\n -- There are 3 insecure configurations\n and\n (\n -- Materialized views don't support RLS so this is insecure by default\n (c.relkind in ('m')) -- m for materialized view\n or\n -- Standard View, accessible to anon or authenticated that is security_definer\n (\n c.relkind = 'v' -- v for view\n -- Exclude security invoker views\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n )\n or\n -- Standard View, security invoker, but no RLS enabled on auth.users\n (\n c.relkind in ('v') -- v for view\n -- is security invoker\n and (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n and not pg_class_auth_users.relrowsecurity\n )\n )\ngroup by\n n.nspname,\n c.relname,\n c.oid)\nunion all\n\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n pc.relrowsecurity as is_rls_active,\n polname as policy_name,\n polpermissive as is_permissive, -- if not, then restrictive\n (select array_agg(r::regrole) from unnest(polroles) as x(r)) as roles,\n case polcmd\n when 'r' then 'SELECT'\n when 'a' then 'INSERT'\n when 'w' then 'UPDATE'\n when 'd' then 'DELETE'\n when '*' then 'ALL'\n end as command,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'auth_rls_initplan' as \"name!\",\n 'Auth RLS Initialization Plan' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if calls to \\`current_setting()\\` and \\`auth.()\\` in RLS policies are being unnecessarily re-evaluated for each row' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that re-evaluates current_setting() or auth.() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \\`auth.()\\` with \\`(select auth.())\\`. See [docs](https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select) for more info.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('auth_rls_init_plan_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n is_rls_active\n -- NOTE: does not include realtime in support of monitoring policies on realtime.messages\n and schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.uid()\n (\n qual like '%auth.uid()%'\n and lower(qual) not like '%select auth.uid()%'\n )\n or (\n qual like '%auth.jwt()%'\n and lower(qual) not like '%select auth.jwt()%'\n )\n or (\n qual like '%auth.role()%'\n and lower(qual) not like '%select auth.role()%'\n )\n or (\n qual like '%auth.email()%'\n and lower(qual) not like '%select auth.email()%'\n )\n or (\n qual like '%current\\_setting(%)%'\n and lower(qual) not like '%select current\\_setting(%)%'\n )\n or (\n with_check like '%auth.uid()%'\n and lower(with_check) not like '%select auth.uid()%'\n )\n or (\n with_check like '%auth.jwt()%'\n and lower(with_check) not like '%select auth.jwt()%'\n )\n or (\n with_check like '%auth.role()%'\n and lower(with_check) not like '%select auth.role()%'\n )\n or (\n with_check like '%auth.email()%'\n and lower(with_check) not like '%select auth.email()%'\n )\n or (\n with_check like '%current\\_setting(%)%'\n and lower(with_check) not like '%select current\\_setting(%)%'\n )\n ))\nunion all\n\n(\nselect\n 'security_definer_view' as \"name!\",\n 'Security Definer View' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects views defined with the SECURITY DEFINER property. These views enforce Postgres permissions and row level security policies (RLS) of the view creator, rather than that of the querying user' as \"description!\",\n format(\n 'View \\`%s.%s\\` is defined with the SECURITY DEFINER property',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view'\n ) as \"metadata!\",\n format(\n 'security_definer_view_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'v'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and substring(pg_catalog.version() from 'PostgreSQL ([0-9]+)') >= '15' -- security invoker was added in pg15\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude views owned by extensions\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n ))\nunion all\n\n(\nselect\n 'rls_disabled_in_public' as \"name!\",\n 'RLS Disabled in Public' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has not been enabled on tables in schemas exposed to PostgREST' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind = 'r' -- regular tables\n -- RLS is disabled\n and not c.relrowsecurity\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n polname as policy_name,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'rls_references_user_metadata' as \"name!\",\n 'RLS references user metadata' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects when Supabase Auth user_metadata is referenced insecurely in a row level security (RLS) policy.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that references Supabase Auth \\`user_metadata\\`. \\`user_metadata\\` is editable by end users and should never be used in a security context.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('rls_references_user_metadata_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.jwt() -> 'user_metadata'\n -- False positives are possible, but it isn't practical to string match\n -- If false positive rate is too high, this expression can iterate\n qual like '%auth.jwt()%user_metadata%'\n or qual like '%current_setting(%request.jwt.claims%)%user_metadata%'\n or with_check like '%auth.jwt()%user_metadata%'\n or with_check like '%current_setting(%request.jwt.claims%)%user_metadata%'\n ))\nunion all\n\n(\nselect\n 'materialized_view_in_api' as \"name!\",\n 'Materialized View in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects materialized views that are accessible over the Data APIs.' as \"description!\",\n format(\n 'Materialized view \\`%s.%s\\` is selectable by anon or authenticated roles',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'materialized view'\n ) as \"metadata!\",\n format(\n 'materialized_view_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'm'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n\n(\nselect\n 'foreign_table_in_api' as \"name!\",\n 'Foreign Table in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects foreign tables that are accessible over APIs. Foreign tables do not respect row level security policies.' as \"description!\",\n format(\n 'Foreign table \\`%s.%s\\` is accessible over APIs',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'foreign table'\n ) as \"metadata!\",\n format(\n 'foreign_table_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'f'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n\n(\nselect\n 'insecure_queue_exposed_in_api' as \"name!\",\n 'Insecure Queue Exposed in API' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where an insecure Queue is exposed over Data APIs' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind in ('r', 'I') -- regular or partitioned tables\n and not c.relrowsecurity -- RLS is disabled\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = 'pgmq' -- tables in the pgmq schema\n and c.relname like 'q_%' -- only queue tables\n -- Constant requirements\n and 'pgmq_public' = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))))\nunion all\n\n(\nselect\n 'fkey_to_auth_unique' as \"name!\",\n 'Foreign Key to Auth Unique Constraint' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects user defined foreign keys to unique constraints in the auth schema.' as \"description!\",\n format(\n 'Table `%s`.`%s` has a foreign key `%s` referencing an auth unique constraint',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname -- fkey name\n ) as \"detail!\",\n 'Drop the foreign key constraint that references the auth schema.' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c_rel.relname,\n 'foreign_key', c.conname\n ) as \"metadata!\",\n format(\n 'fkey_to_auth_unique_%s_%s_%s',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_constraint c\n join pg_catalog.pg_class c_rel\n on c.conrelid = c_rel.oid\n join pg_catalog.pg_namespace n\n on c_rel.relnamespace = n.oid\n join pg_catalog.pg_class ref_rel\n on c.confrelid = ref_rel.oid\n join pg_catalog.pg_namespace cn\n on ref_rel.relnamespace = cn.oid\n join pg_catalog.pg_index i\n on c.conindid = i.indexrelid\nwhere c.contype = 'f'\n and cn.nspname = 'auth'\n and i.indisunique\n and not i.indisprimary)\n", + "describe": { + "columns": [ + { + "ordinal": 0, + "name": "name!", + "type_info": "Text" + }, + { + "ordinal": 1, + "name": "title!", + "type_info": "Text" + }, + { + "ordinal": 2, + "name": "level!", + "type_info": "Text" + }, + { + "ordinal": 3, + "name": "facing!", + "type_info": "Text" + }, + { + "ordinal": 4, + "name": "categories!", + "type_info": "TextArray" + }, + { + "ordinal": 5, + "name": "description!", + "type_info": "Text" + }, + { + "ordinal": 6, + "name": "detail!", + "type_info": "Text" + }, + { + "ordinal": 7, + "name": "remediation!", + "type_info": "Text" + }, + { + "ordinal": 8, + "name": "metadata!", + "type_info": "Jsonb" + }, + { + "ordinal": 9, + "name": "cache_key!", + "type_info": "Text" + } + ], + "parameters": { + "Left": [] + }, + "nullable": [ + null, + null, + null, + null, + null, + null, + null, + null, + null, + null + ] + }, + "hash": "425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69" +} diff --git a/crates/pgls_splinter/build.rs b/crates/pgls_splinter/build.rs index fc12a7305..be09b9e6d 100644 --- a/crates/pgls_splinter/build.rs +++ b/crates/pgls_splinter/build.rs @@ -5,10 +5,24 @@ use std::path::Path; // Update this commit SHA to pull in a new version of splinter.sql const SPLINTER_COMMIT_SHA: &str = "27ea2ece65464213e466cd969cc61b6940d16219"; +// Rules that require Supabase-specific infrastructure (auth schema, anon/authenticated roles, pgrst.db_schemas) +const SUPABASE_ONLY_RULES: &[&str] = &[ + "auth_users_exposed", + "auth_rls_initplan", + "rls_disabled_in_public", + "security_definer_view", + "rls_references_user_metadata", + "materialized_view_in_api", + "foreign_table_in_api", + "insecure_queue_exposed_in_api", + "fkey_to_auth_unique", +]; + fn main() { let out_dir = env::var("CARGO_MANIFEST_DIR").unwrap(); let vendor_dir = Path::new(&out_dir).join("vendor"); - let sql_file = vendor_dir.join("splinter.sql"); + let generic_sql_file = vendor_dir.join("splinter_generic.sql"); + let supabase_sql_file = vendor_dir.join("splinter_supabase.sql"); let sha_file = vendor_dir.join("COMMIT_SHA.txt"); // Create vendor directory if it doesn't exist @@ -17,22 +31,23 @@ fn main() { } // Check if we need to download - let needs_download = if !sql_file.exists() || !sha_file.exists() { - true - } else { - // Check if stored SHA matches current constant - let stored_sha = fs::read_to_string(&sha_file) - .expect("Failed to read COMMIT_SHA.txt") - .trim() - .to_string(); - stored_sha != SPLINTER_COMMIT_SHA - }; + let needs_download = + if !generic_sql_file.exists() || !supabase_sql_file.exists() || !sha_file.exists() { + true + } else { + // Check if stored SHA matches current constant + let stored_sha = fs::read_to_string(&sha_file) + .expect("Failed to read COMMIT_SHA.txt") + .trim() + .to_string(); + stored_sha != SPLINTER_COMMIT_SHA + }; if needs_download { println!( "cargo:warning=Downloading splinter.sql from GitHub (commit: {SPLINTER_COMMIT_SHA})" ); - download_and_process_sql(&sql_file); + download_and_process_sql(&generic_sql_file, &supabase_sql_file); fs::write(&sha_file, SPLINTER_COMMIT_SHA).expect("Failed to write COMMIT_SHA.txt"); } @@ -41,7 +56,7 @@ fn main() { println!("cargo:rerun-if-changed=vendor/COMMIT_SHA.txt"); } -fn download_and_process_sql(dest_path: &Path) { +fn download_and_process_sql(generic_dest: &Path, supabase_dest: &Path) { let url = format!( "https://raw.githubusercontent.com/supabase/splinter/{SPLINTER_COMMIT_SHA}/splinter.sql" ); @@ -61,10 +76,16 @@ fn download_and_process_sql(dest_path: &Path) { // Add "!" suffix to column aliases for sqlx non-null checking processed_content = add_not_null_markers(&processed_content); - // Write to destination - fs::write(dest_path, processed_content).expect("Failed to write splinter.sql"); + // Split into generic and Supabase-specific queries + let (generic_queries, supabase_queries) = split_queries(&processed_content); - println!("cargo:warning=Successfully downloaded and processed splinter.sql"); + // Write to destination files + fs::write(generic_dest, generic_queries).expect("Failed to write splinter_generic.sql"); + fs::write(supabase_dest, supabase_queries).expect("Failed to write splinter_supabase.sql"); + + println!( + "cargo:warning=Successfully downloaded and processed splinter.sql into generic and Supabase-specific files" + ); } fn remove_set_search_path(content: &str) -> String { @@ -107,3 +128,39 @@ fn add_not_null_markers(content: &str) -> String { result } + +fn split_queries(content: &str) -> (String, String) { + // Split the union all queries based on rule names + let queries: Vec<&str> = content.split("union all").collect(); + + let mut generic_queries = Vec::new(); + let mut supabase_queries = Vec::new(); + + for query in queries { + // Extract the rule name from the query (it's the first 'name' field) + let is_supabase = SUPABASE_ONLY_RULES + .iter() + .any(|rule| query.contains(&format!("'{rule}' as \"name!\""))); + + if is_supabase { + supabase_queries.push(query); + } else { + generic_queries.push(query); + } + } + + // Join queries with "union all" and wrap in parentheses + let generic_sql = if generic_queries.is_empty() { + String::new() + } else { + generic_queries.join("union all\n") + }; + + let supabase_sql = if supabase_queries.is_empty() { + String::new() + } else { + supabase_queries.join("union all\n") + }; + + (generic_sql, supabase_sql) +} diff --git a/crates/pgls_splinter/src/convert.rs b/crates/pgls_splinter/src/convert.rs index dc445deee..11d01f7e1 100644 --- a/crates/pgls_splinter/src/convert.rs +++ b/crates/pgls_splinter/src/convert.rs @@ -1,4 +1,4 @@ -use pgls_diagnostics::{Category, Severity, category}; +use pgls_diagnostics::{category, Category, Severity}; use serde_json::Value; use crate::{SplinterAdvices, SplinterDiagnostic, SplinterQueryResult}; @@ -27,13 +27,45 @@ impl From for SplinterDiagnostic { schema, object_name, object_type, - remediation_url: result.remediation, + remediation_url: build_remediation_url(&result.name), additional_metadata, }, } } } +/// Build remediation URL from rule name +/// Maps rule names to their Supabase linter documentation +fn build_remediation_url(name: &str) -> String { + // Map rule names to their lint IDs + let lint_id = match name { + "unindexed_foreign_keys" => "0001_unindexed_foreign_keys", + "auth_users_exposed" => "0002_auth_users_exposed", + "auth_rls_initplan" => "0003_auth_rls_initplan", + "no_primary_key" => "0004_no_primary_key", + "unused_index" => "0005_unused_index", + "multiple_permissive_policies" => "0006_multiple_permissive_policies", + "policy_exists_rls_disabled" => "0007_policy_exists_rls_disabled", + "rls_enabled_no_policy" => "0008_rls_enabled_no_policy", + "duplicate_index" => "0009_duplicate_index", + "security_definer_view" => "0010_security_definer_view", + "function_search_path_mutable" => "0011_function_search_path_mutable", + "rls_disabled_in_public" => "0013_rls_disabled_in_public", + "extension_in_public" => "0014_extension_in_public", + "rls_references_user_metadata" => "0015_rls_references_user_metadata", + "materialized_view_in_api" => "0016_materialized_view_in_api", + "foreign_table_in_api" => "0017_foreign_table_in_api", + "unsupported_reg_types" => "unsupported_reg_types", + "insecure_queue_exposed_in_api" => "0019_insecure_queue_exposed_in_api", + "table_bloat" => "0020_table_bloat", + "fkey_to_auth_unique" => "0021_fkey_to_auth_unique", + "extension_versions_outdated" => "0022_extension_versions_outdated", + _ => return format!("https://supabase.com/docs/guides/database/database-linter"), + }; + + format!("https://supabase.com/docs/guides/database/database-linter?lint={lint_id}") +} + /// Parse severity level from the query result fn parse_severity(level: &str) -> Severity { match level { diff --git a/crates/pgls_splinter/src/lib.rs b/crates/pgls_splinter/src/lib.rs index 11cfb3277..b32df2329 100644 --- a/crates/pgls_splinter/src/lib.rs +++ b/crates/pgls_splinter/src/lib.rs @@ -12,7 +12,7 @@ pub struct SplinterParams<'a> { pub conn: &'a PgPool, } -async fn check_required_roles(conn: &PgPool) -> Result { +async fn check_supabase_roles(conn: &PgPool) -> Result { let required_roles = ["anon", "authenticated", "service_role"]; let existing_roles: Vec = @@ -32,17 +32,19 @@ async fn check_required_roles(conn: &PgPool) -> Result { pub async fn run_splinter( params: SplinterParams<'_>, ) -> Result, sqlx::Error> { - // check if required supabase roles exist - // if they don't exist, return empty diagnostics since splinter is supabase-specific - // opened an issue to make it less supabase-specific: https://github.com/supabase/splinter/issues/135 - let has_roles = check_required_roles(params.conn).await?; - if !has_roles { - return Ok(Vec::new()); - } + let mut all_results = Vec::new(); + + let generic_results = query::load_generic_splinter_results(params.conn).await?; + all_results.extend(generic_results); - let results = query::load_splinter_results(params.conn).await?; + // Only run Supabase-specific rules if the required roles exist + let has_supabase_roles = check_supabase_roles(params.conn).await?; + if has_supabase_roles { + let supabase_results = query::load_supabase_splinter_results(params.conn).await?; + all_results.extend(supabase_results); + } - let diagnostics: Vec = results.into_iter().map(Into::into).collect(); + let diagnostics: Vec = all_results.into_iter().map(Into::into).collect(); Ok(diagnostics) } diff --git a/crates/pgls_splinter/src/query.rs b/crates/pgls_splinter/src/query.rs index 6336d0353..4c7a7ffa4 100644 --- a/crates/pgls_splinter/src/query.rs +++ b/crates/pgls_splinter/src/query.rs @@ -38,7 +38,9 @@ pub struct SplinterQueryResult { pub cache_key: String, } -pub async fn load_splinter_results(pool: &PgPool) -> Result, sqlx::Error> { +pub async fn load_generic_splinter_results( + pool: &PgPool, +) -> Result, sqlx::Error> { let mut tx = pool.begin().await?; // this is done by the splinter.sql file normally, but we remove it so that sqlx can work with @@ -47,7 +49,27 @@ pub async fn load_splinter_results(pool: &PgPool) -> Result Result, sqlx::Error> { + let mut tx = pool.begin().await?; + + // this is done by the splinter.sql file normally, but we remove it so that sqlx can work with + // the file properly. + sqlx::query("set local search_path = ''") + .execute(&mut *tx) + .await?; + + let results = sqlx::query_file_as!(SplinterQueryResult, "vendor/splinter_supabase.sql") .fetch_all(&mut *tx) .await?; diff --git a/crates/pgls_splinter/tests/diagnostics.rs b/crates/pgls_splinter/tests/diagnostics.rs index 576b69952..53713989a 100644 --- a/crates/pgls_splinter/tests/diagnostics.rs +++ b/crates/pgls_splinter/tests/diagnostics.rs @@ -1,6 +1,6 @@ use pgls_console::fmt::{Formatter, HTML}; use pgls_diagnostics::{Diagnostic, LogCategory, Visit}; -use pgls_splinter::{SplinterParams, run_splinter}; +use pgls_splinter::{run_splinter, SplinterParams}; use sqlx::PgPool; use std::fmt::Write; use std::io; @@ -247,14 +247,31 @@ async fn multiple_issues(test_db: PgPool) { } #[sqlx::test(migrator = "pgls_test_utils::MIGRATIONS")] -async fn missing_roles_returns_empty(test_db: PgPool) { +async fn missing_roles_runs_generic_checks_only(test_db: PgPool) { + // Without Supabase roles, generic rules should still run + // but Supabase-specific rules should be skipped let diagnostics = run_splinter(SplinterParams { conn: &test_db }) .await - .expect("Should not error when roles are missing"); + .expect("Should not error when Supabase roles are missing"); assert!( diagnostics.is_empty(), - "Expected empty diagnostics when Supabase roles are missing, but got {} diagnostics", + "Expected empty diagnostics for a clean database without Supabase roles, but got {} diagnostics", diagnostics.len() ); + + // Now create a table with a generic issue (no primary key) + sqlx::raw_sql("CREATE TABLE public.test_table (name text)") + .execute(&test_db) + .await + .expect("Failed to create test table"); + + let diagnostics_with_issue = run_splinter(SplinterParams { conn: &test_db }) + .await + .expect("Should not error when checking for issues"); + + assert!( + !diagnostics_with_issue.is_empty(), + "Expected to detect generic issues (no primary key) even without Supabase roles" + ); } diff --git a/crates/pgls_splinter/vendor/COMMIT_SHA.txt b/crates/pgls_splinter/vendor/COMMIT_SHA.txt index e211f5f15..7ca1b8f8c 100644 --- a/crates/pgls_splinter/vendor/COMMIT_SHA.txt +++ b/crates/pgls_splinter/vendor/COMMIT_SHA.txt @@ -1 +1 @@ -27ea2ece65464213e466cd969cc61b6940d16219 +27ea2ece65464213e466cd969cc61b6940d16219 \ No newline at end of file diff --git a/crates/pgls_splinter/vendor/splinter.sql b/crates/pgls_splinter/vendor/splinter_generic.sql similarity index 53% rename from crates/pgls_splinter/vendor/splinter.sql rename to crates/pgls_splinter/vendor/splinter_generic.sql index 7f479898e..8421701f9 100644 --- a/crates/pgls_splinter/vendor/splinter.sql +++ b/crates/pgls_splinter/vendor/splinter_generic.sql @@ -72,196 +72,7 @@ order by fk.table_name, fk.fkey_name) union all -( -select - 'auth_users_exposed' as "name!", - 'Exposed Auth Users' as "title!", - 'ERROR' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects if auth.users is exposed to anon or authenticated roles via a view or materialized view in schemas exposed to PostgREST, potentially compromising user data security.' as "description!", - format( - 'View/Materialized View "%s" in the public schema may expose \`auth.users\` data to anon or authenticated roles.', - c.relname - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed' as "remediation!", - jsonb_build_object( - 'schema', n.nspname, - 'name', c.relname, - 'type', 'view', - 'exposed_to', array_remove(array_agg(DISTINCT case when pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') then 'anon' when pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') then 'authenticated' end), null) - ) as "metadata!", - format('auth_users_exposed_%s_%s', n.nspname, c.relname) as "cache_key!" -from - -- Identify the oid for auth.users - pg_catalog.pg_class auth_users_pg_class - join pg_catalog.pg_namespace auth_users_pg_namespace - on auth_users_pg_class.relnamespace = auth_users_pg_namespace.oid - and auth_users_pg_class.relname = 'users' - and auth_users_pg_namespace.nspname = 'auth' - -- Depends on auth.users - join pg_catalog.pg_depend d - on d.refobjid = auth_users_pg_class.oid - join pg_catalog.pg_rewrite r - on r.oid = d.objid - join pg_catalog.pg_class c - on c.oid = r.ev_class - join pg_catalog.pg_namespace n - on n.oid = c.relnamespace - join pg_catalog.pg_class pg_class_auth_users - on d.refobjid = pg_class_auth_users.oid -where - d.deptype = 'n' - and ( - pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') - or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') - ) - and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) - -- Exclude self - and c.relname <> '0002_auth_users_exposed' - -- There are 3 insecure configurations - and - ( - -- Materialized views don't support RLS so this is insecure by default - (c.relkind in ('m')) -- m for materialized view - or - -- Standard View, accessible to anon or authenticated that is security_definer - ( - c.relkind = 'v' -- v for view - -- Exclude security invoker views - and not ( - lower(coalesce(c.reloptions::text,'{}'))::text[] - && array[ - 'security_invoker=1', - 'security_invoker=true', - 'security_invoker=yes', - 'security_invoker=on' - ] - ) - ) - or - -- Standard View, security invoker, but no RLS enabled on auth.users - ( - c.relkind in ('v') -- v for view - -- is security invoker - and ( - lower(coalesce(c.reloptions::text,'{}'))::text[] - && array[ - 'security_invoker=1', - 'security_invoker=true', - 'security_invoker=yes', - 'security_invoker=on' - ] - ) - and not pg_class_auth_users.relrowsecurity - ) - ) -group by - n.nspname, - c.relname, - c.oid) -union all -( -with policies as ( - select - nsp.nspname as schema_name, - pb.tablename as table_name, - pc.relrowsecurity as is_rls_active, - polname as policy_name, - polpermissive as is_permissive, -- if not, then restrictive - (select array_agg(r::regrole) from unnest(polroles) as x(r)) as roles, - case polcmd - when 'r' then 'SELECT' - when 'a' then 'INSERT' - when 'w' then 'UPDATE' - when 'd' then 'DELETE' - when '*' then 'ALL' - end as command, - qual, - with_check - from - pg_catalog.pg_policy pa - join pg_catalog.pg_class pc - on pa.polrelid = pc.oid - join pg_catalog.pg_namespace nsp - on pc.relnamespace = nsp.oid - join pg_catalog.pg_policies pb - on pc.relname = pb.tablename - and nsp.nspname = pb.schemaname - and pa.polname = pb.policyname -) -select - 'auth_rls_initplan' as "name!", - 'Auth RLS Initialization Plan' as "title!", - 'WARN' as "level!", - 'EXTERNAL' as "facing!", - array['PERFORMANCE'] as "categories!", - 'Detects if calls to \`current_setting()\` and \`auth.()\` in RLS policies are being unnecessarily re-evaluated for each row' as "description!", - format( - 'Table \`%s.%s\` has a row level security policy \`%s\` that re-evaluates current_setting() or auth.() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \`auth.()\` with \`(select auth.())\`. See [docs](https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select) for more info.', - schema_name, - table_name, - policy_name - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan' as "remediation!", - jsonb_build_object( - 'schema', schema_name, - 'name', table_name, - 'type', 'table' - ) as "metadata!", - format('auth_rls_init_plan_%s_%s_%s', schema_name, table_name, policy_name) as "cache_key!" -from - policies -where - is_rls_active - -- NOTE: does not include realtime in support of monitoring policies on realtime.messages - and schema_name not in ( - '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' - ) - and ( - -- Example: auth.uid() - ( - qual like '%auth.uid()%' - and lower(qual) not like '%select auth.uid()%' - ) - or ( - qual like '%auth.jwt()%' - and lower(qual) not like '%select auth.jwt()%' - ) - or ( - qual like '%auth.role()%' - and lower(qual) not like '%select auth.role()%' - ) - or ( - qual like '%auth.email()%' - and lower(qual) not like '%select auth.email()%' - ) - or ( - qual like '%current\_setting(%)%' - and lower(qual) not like '%select current\_setting(%)%' - ) - or ( - with_check like '%auth.uid()%' - and lower(with_check) not like '%select auth.uid()%' - ) - or ( - with_check like '%auth.jwt()%' - and lower(with_check) not like '%select auth.jwt()%' - ) - or ( - with_check like '%auth.role()%' - and lower(with_check) not like '%select auth.role()%' - ) - or ( - with_check like '%auth.email()%' - and lower(with_check) not like '%select auth.email()%' - ) - or ( - with_check like '%current\_setting(%)%' - and lower(with_check) not like '%select current\_setting(%)%' - ) - )) -union all + ( select 'no_primary_key' as "name!", @@ -308,6 +119,7 @@ group by having max(coalesce(pgi.indisprimary, false)::int) = 0) union all + ( select 'unused_index' as "name!", @@ -351,6 +163,7 @@ where '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' )) union all + ( select 'multiple_permissive_policies' as "name!", @@ -424,6 +237,7 @@ group by having count(1) > 1) union all + ( select 'policy_exists_rls_disabled' as "name!", @@ -470,6 +284,7 @@ group by n.nspname, c.relname) union all + ( select 'rls_enabled_no_policy' as "name!", @@ -516,6 +331,7 @@ group by n.nspname, c.relname) union all + ( select 'duplicate_index' as "name!", @@ -571,59 +387,7 @@ group by having count(*) > 1) union all -( -select - 'security_definer_view' as "name!", - 'Security Definer View' as "title!", - 'ERROR' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects views defined with the SECURITY DEFINER property. These views enforce Postgres permissions and row level security policies (RLS) of the view creator, rather than that of the querying user' as "description!", - format( - 'View \`%s.%s\` is defined with the SECURITY DEFINER property', - n.nspname, - c.relname - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view' as "remediation!", - jsonb_build_object( - 'schema', n.nspname, - 'name', c.relname, - 'type', 'view' - ) as "metadata!", - format( - 'security_definer_view_%s_%s', - n.nspname, - c.relname - ) as "cache_key!" -from - pg_catalog.pg_class c - join pg_catalog.pg_namespace n - on n.oid = c.relnamespace - left join pg_catalog.pg_depend dep - on c.oid = dep.objid - and dep.deptype = 'e' -where - c.relkind = 'v' - and ( - pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') - or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') - ) - and substring(pg_catalog.version() from 'PostgreSQL ([0-9]+)') >= '15' -- security invoker was added in pg15 - and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) - and n.nspname not in ( - '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' - ) - and dep.objid is null -- exclude views owned by extensions - and not ( - lower(coalesce(c.reloptions::text,'{}'))::text[] - && array[ - 'security_invoker=1', - 'security_invoker=true', - 'security_invoker=yes', - 'security_invoker=on' - ] - )) -union all + ( select 'function_search_path_mutable' as "name!", @@ -668,47 +432,7 @@ where where config like 'search_path=%' )) union all -( -select - 'rls_disabled_in_public' as "name!", - 'RLS Disabled in Public' as "title!", - 'ERROR' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects cases where row level security (RLS) has not been enabled on tables in schemas exposed to PostgREST' as "description!", - format( - 'Table \`%s.%s\` is public, but RLS has not been enabled.', - n.nspname, - c.relname - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public' as "remediation!", - jsonb_build_object( - 'schema', n.nspname, - 'name', c.relname, - 'type', 'table' - ) as "metadata!", - format( - 'rls_disabled_in_public_%s_%s', - n.nspname, - c.relname - ) as "cache_key!" -from - pg_catalog.pg_class c - join pg_catalog.pg_namespace n - on c.relnamespace = n.oid -where - c.relkind = 'r' -- regular tables - -- RLS is disabled - and not c.relrowsecurity - and ( - pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') - or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') - ) - and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) - and n.nspname not in ( - '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' - )) -union all + ( select 'extension_in_public' as "name!", @@ -743,147 +467,7 @@ where -- is not appropriate here as it would evaluate true for the extensions schema and pe.extnamespace::regnamespace::text = 'public') union all -( -with policies as ( - select - nsp.nspname as schema_name, - pb.tablename as table_name, - polname as policy_name, - qual, - with_check - from - pg_catalog.pg_policy pa - join pg_catalog.pg_class pc - on pa.polrelid = pc.oid - join pg_catalog.pg_namespace nsp - on pc.relnamespace = nsp.oid - join pg_catalog.pg_policies pb - on pc.relname = pb.tablename - and nsp.nspname = pb.schemaname - and pa.polname = pb.policyname -) -select - 'rls_references_user_metadata' as "name!", - 'RLS references user metadata' as "title!", - 'ERROR' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects when Supabase Auth user_metadata is referenced insecurely in a row level security (RLS) policy.' as "description!", - format( - 'Table \`%s.%s\` has a row level security policy \`%s\` that references Supabase Auth \`user_metadata\`. \`user_metadata\` is editable by end users and should never be used in a security context.', - schema_name, - table_name, - policy_name - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata' as "remediation!", - jsonb_build_object( - 'schema', schema_name, - 'name', table_name, - 'type', 'table' - ) as "metadata!", - format('rls_references_user_metadata_%s_%s_%s', schema_name, table_name, policy_name) as "cache_key!" -from - policies -where - schema_name not in ( - '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' - ) - and ( - -- Example: auth.jwt() -> 'user_metadata' - -- False positives are possible, but it isn't practical to string match - -- If false positive rate is too high, this expression can iterate - qual like '%auth.jwt()%user_metadata%' - or qual like '%current_setting(%request.jwt.claims%)%user_metadata%' - or with_check like '%auth.jwt()%user_metadata%' - or with_check like '%current_setting(%request.jwt.claims%)%user_metadata%' - )) -union all -( -select - 'materialized_view_in_api' as "name!", - 'Materialized View in API' as "title!", - 'WARN' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects materialized views that are accessible over the Data APIs.' as "description!", - format( - 'Materialized view \`%s.%s\` is selectable by anon or authenticated roles', - n.nspname, - c.relname - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api' as "remediation!", - jsonb_build_object( - 'schema', n.nspname, - 'name', c.relname, - 'type', 'materialized view' - ) as "metadata!", - format( - 'materialized_view_in_api_%s_%s', - n.nspname, - c.relname - ) as "cache_key!" -from - pg_catalog.pg_class c - join pg_catalog.pg_namespace n - on n.oid = c.relnamespace - left join pg_catalog.pg_depend dep - on c.oid = dep.objid - and dep.deptype = 'e' -where - c.relkind = 'm' - and ( - pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') - or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') - ) - and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) - and n.nspname not in ( - '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' - ) - and dep.objid is null) -union all -( -select - 'foreign_table_in_api' as "name!", - 'Foreign Table in API' as "title!", - 'WARN' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects foreign tables that are accessible over APIs. Foreign tables do not respect row level security policies.' as "description!", - format( - 'Foreign table \`%s.%s\` is accessible over APIs', - n.nspname, - c.relname - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api' as "remediation!", - jsonb_build_object( - 'schema', n.nspname, - 'name', c.relname, - 'type', 'foreign table' - ) as "metadata!", - format( - 'foreign_table_in_api_%s_%s', - n.nspname, - c.relname - ) as "cache_key!" -from - pg_catalog.pg_class c - join pg_catalog.pg_namespace n - on n.oid = c.relnamespace - left join pg_catalog.pg_depend dep - on c.oid = dep.objid - and dep.deptype = 'e' -where - c.relkind = 'f' - and ( - pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') - or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') - ) - and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) - and n.nspname not in ( - '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' - ) - and dep.objid is null) -union all + ( select 'unsupported_reg_types' as "name!", @@ -927,46 +511,7 @@ where and t.typname in ('regcollation', 'regconfig', 'regdictionary', 'regnamespace', 'regoper', 'regoperator', 'regproc', 'regprocedure') and n.nspname not in ('pg_catalog', 'information_schema', 'pgsodium')) union all -( -select - 'insecure_queue_exposed_in_api' as "name!", - 'Insecure Queue Exposed in API' as "title!", - 'ERROR' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects cases where an insecure Queue is exposed over Data APIs' as "description!", - format( - 'Table \`%s.%s\` is public, but RLS has not been enabled.', - n.nspname, - c.relname - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api' as "remediation!", - jsonb_build_object( - 'schema', n.nspname, - 'name', c.relname, - 'type', 'table' - ) as "metadata!", - format( - 'rls_disabled_in_public_%s_%s', - n.nspname, - c.relname - ) as "cache_key!" -from - pg_catalog.pg_class c - join pg_catalog.pg_namespace n - on c.relnamespace = n.oid -where - c.relkind in ('r', 'I') -- regular or partitioned tables - and not c.relrowsecurity -- RLS is disabled - and ( - pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') - or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') - ) - and n.nspname = 'pgmq' -- tables in the pgmq schema - and c.relname like 'q_%' -- only queue tables - -- Constant requirements - and 'pgmq_public' = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))) -union all + ( with constants as ( select current_setting('block_size')::numeric as bs, 23 as hdr, 4 as ma @@ -1046,7 +591,7 @@ select bloat_data.schemaname, bloat_data.object_name ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat' as "remediation!", + 'Consider running vacuum full (WARNING: incurs downtime) and tweaking autovacuum settings to reduce bloat.' as "remediation!", jsonb_build_object( 'schema', bloat_data.schemaname, 'name', bloat_data.object_name, @@ -1066,49 +611,7 @@ order by schemaname, object_name) union all -( -select - 'fkey_to_auth_unique' as "name!", - 'Foreign Key to Auth Unique Constraint' as "title!", - 'ERROR' as "level!", - 'EXTERNAL' as "facing!", - array['SECURITY'] as "categories!", - 'Detects user defined foreign keys to unique constraints in the auth schema.' as "description!", - format( - 'Table `%s`.`%s` has a foreign key `%s` referencing an auth unique constraint', - n.nspname, -- referencing schema - c_rel.relname, -- referencing table - c.conname -- fkey name - ) as "detail!", - 'https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique' as "remediation!", - jsonb_build_object( - 'schema', n.nspname, - 'name', c_rel.relname, - 'foreign_key', c.conname - ) as "metadata!", - format( - 'fkey_to_auth_unique_%s_%s_%s', - n.nspname, -- referencing schema - c_rel.relname, -- referencing table - c.conname - ) as "cache_key!" -from - pg_catalog.pg_constraint c - join pg_catalog.pg_class c_rel - on c.conrelid = c_rel.oid - join pg_catalog.pg_namespace n - on c_rel.relnamespace = n.oid - join pg_catalog.pg_class ref_rel - on c.confrelid = ref_rel.oid - join pg_catalog.pg_namespace cn - on ref_rel.relnamespace = cn.oid - join pg_catalog.pg_index i - on c.conindid = i.indexrelid -where c.contype = 'f' - and cn.nspname = 'auth' - and i.indisunique - and not i.indisprimary) -union all + ( select 'extension_versions_outdated' as "name!", diff --git a/crates/pgls_splinter/vendor/splinter_supabase.sql b/crates/pgls_splinter/vendor/splinter_supabase.sql new file mode 100644 index 000000000..79387c083 --- /dev/null +++ b/crates/pgls_splinter/vendor/splinter_supabase.sql @@ -0,0 +1,516 @@ + +( +select + 'auth_users_exposed' as "name!", + 'Exposed Auth Users' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects if auth.users is exposed to anon or authenticated roles via a view or materialized view in schemas exposed to PostgREST, potentially compromising user data security.' as "description!", + format( + 'View/Materialized View "%s" in the public schema may expose \`auth.users\` data to anon or authenticated roles.', + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'view', + 'exposed_to', array_remove(array_agg(DISTINCT case when pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') then 'anon' when pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') then 'authenticated' end), null) + ) as "metadata!", + format('auth_users_exposed_%s_%s', n.nspname, c.relname) as "cache_key!" +from + -- Identify the oid for auth.users + pg_catalog.pg_class auth_users_pg_class + join pg_catalog.pg_namespace auth_users_pg_namespace + on auth_users_pg_class.relnamespace = auth_users_pg_namespace.oid + and auth_users_pg_class.relname = 'users' + and auth_users_pg_namespace.nspname = 'auth' + -- Depends on auth.users + join pg_catalog.pg_depend d + on d.refobjid = auth_users_pg_class.oid + join pg_catalog.pg_rewrite r + on r.oid = d.objid + join pg_catalog.pg_class c + on c.oid = r.ev_class + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + join pg_catalog.pg_class pg_class_auth_users + on d.refobjid = pg_class_auth_users.oid +where + d.deptype = 'n' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + -- Exclude self + and c.relname <> '0002_auth_users_exposed' + -- There are 3 insecure configurations + and + ( + -- Materialized views don't support RLS so this is insecure by default + (c.relkind in ('m')) -- m for materialized view + or + -- Standard View, accessible to anon or authenticated that is security_definer + ( + c.relkind = 'v' -- v for view + -- Exclude security invoker views + and not ( + lower(coalesce(c.reloptions::text,'{}'))::text[] + && array[ + 'security_invoker=1', + 'security_invoker=true', + 'security_invoker=yes', + 'security_invoker=on' + ] + ) + ) + or + -- Standard View, security invoker, but no RLS enabled on auth.users + ( + c.relkind in ('v') -- v for view + -- is security invoker + and ( + lower(coalesce(c.reloptions::text,'{}'))::text[] + && array[ + 'security_invoker=1', + 'security_invoker=true', + 'security_invoker=yes', + 'security_invoker=on' + ] + ) + and not pg_class_auth_users.relrowsecurity + ) + ) +group by + n.nspname, + c.relname, + c.oid) +union all + +( +with policies as ( + select + nsp.nspname as schema_name, + pb.tablename as table_name, + pc.relrowsecurity as is_rls_active, + polname as policy_name, + polpermissive as is_permissive, -- if not, then restrictive + (select array_agg(r::regrole) from unnest(polroles) as x(r)) as roles, + case polcmd + when 'r' then 'SELECT' + when 'a' then 'INSERT' + when 'w' then 'UPDATE' + when 'd' then 'DELETE' + when '*' then 'ALL' + end as command, + qual, + with_check + from + pg_catalog.pg_policy pa + join pg_catalog.pg_class pc + on pa.polrelid = pc.oid + join pg_catalog.pg_namespace nsp + on pc.relnamespace = nsp.oid + join pg_catalog.pg_policies pb + on pc.relname = pb.tablename + and nsp.nspname = pb.schemaname + and pa.polname = pb.policyname +) +select + 'auth_rls_initplan' as "name!", + 'Auth RLS Initialization Plan' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['PERFORMANCE'] as "categories!", + 'Detects if calls to \`current_setting()\` and \`auth.()\` in RLS policies are being unnecessarily re-evaluated for each row' as "description!", + format( + 'Table \`%s.%s\` has a row level security policy \`%s\` that re-evaluates current_setting() or auth.() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \`auth.()\` with \`(select auth.())\`. See [docs](https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select) for more info.', + schema_name, + table_name, + policy_name + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan' as "remediation!", + jsonb_build_object( + 'schema', schema_name, + 'name', table_name, + 'type', 'table' + ) as "metadata!", + format('auth_rls_init_plan_%s_%s_%s', schema_name, table_name, policy_name) as "cache_key!" +from + policies +where + is_rls_active + -- NOTE: does not include realtime in support of monitoring policies on realtime.messages + and schema_name not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and ( + -- Example: auth.uid() + ( + qual like '%auth.uid()%' + and lower(qual) not like '%select auth.uid()%' + ) + or ( + qual like '%auth.jwt()%' + and lower(qual) not like '%select auth.jwt()%' + ) + or ( + qual like '%auth.role()%' + and lower(qual) not like '%select auth.role()%' + ) + or ( + qual like '%auth.email()%' + and lower(qual) not like '%select auth.email()%' + ) + or ( + qual like '%current\_setting(%)%' + and lower(qual) not like '%select current\_setting(%)%' + ) + or ( + with_check like '%auth.uid()%' + and lower(with_check) not like '%select auth.uid()%' + ) + or ( + with_check like '%auth.jwt()%' + and lower(with_check) not like '%select auth.jwt()%' + ) + or ( + with_check like '%auth.role()%' + and lower(with_check) not like '%select auth.role()%' + ) + or ( + with_check like '%auth.email()%' + and lower(with_check) not like '%select auth.email()%' + ) + or ( + with_check like '%current\_setting(%)%' + and lower(with_check) not like '%select current\_setting(%)%' + ) + )) +union all + +( +select + 'security_definer_view' as "name!", + 'Security Definer View' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects views defined with the SECURITY DEFINER property. These views enforce Postgres permissions and row level security policies (RLS) of the view creator, rather than that of the querying user' as "description!", + format( + 'View \`%s.%s\` is defined with the SECURITY DEFINER property', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'view' + ) as "metadata!", + format( + 'security_definer_view_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'v' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and substring(pg_catalog.version() from 'PostgreSQL ([0-9]+)') >= '15' -- security invoker was added in pg15 + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null -- exclude views owned by extensions + and not ( + lower(coalesce(c.reloptions::text,'{}'))::text[] + && array[ + 'security_invoker=1', + 'security_invoker=true', + 'security_invoker=yes', + 'security_invoker=on' + ] + )) +union all + +( +select + 'rls_disabled_in_public' as "name!", + 'RLS Disabled in Public' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects cases where row level security (RLS) has not been enabled on tables in schemas exposed to PostgREST' as "description!", + format( + 'Table \`%s.%s\` is public, but RLS has not been enabled.', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'table' + ) as "metadata!", + format( + 'rls_disabled_in_public_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid +where + c.relkind = 'r' -- regular tables + -- RLS is disabled + and not c.relrowsecurity + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + )) +union all + +( +with policies as ( + select + nsp.nspname as schema_name, + pb.tablename as table_name, + polname as policy_name, + qual, + with_check + from + pg_catalog.pg_policy pa + join pg_catalog.pg_class pc + on pa.polrelid = pc.oid + join pg_catalog.pg_namespace nsp + on pc.relnamespace = nsp.oid + join pg_catalog.pg_policies pb + on pc.relname = pb.tablename + and nsp.nspname = pb.schemaname + and pa.polname = pb.policyname +) +select + 'rls_references_user_metadata' as "name!", + 'RLS references user metadata' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects when Supabase Auth user_metadata is referenced insecurely in a row level security (RLS) policy.' as "description!", + format( + 'Table \`%s.%s\` has a row level security policy \`%s\` that references Supabase Auth \`user_metadata\`. \`user_metadata\` is editable by end users and should never be used in a security context.', + schema_name, + table_name, + policy_name + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata' as "remediation!", + jsonb_build_object( + 'schema', schema_name, + 'name', table_name, + 'type', 'table' + ) as "metadata!", + format('rls_references_user_metadata_%s_%s_%s', schema_name, table_name, policy_name) as "cache_key!" +from + policies +where + schema_name not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and ( + -- Example: auth.jwt() -> 'user_metadata' + -- False positives are possible, but it isn't practical to string match + -- If false positive rate is too high, this expression can iterate + qual like '%auth.jwt()%user_metadata%' + or qual like '%current_setting(%request.jwt.claims%)%user_metadata%' + or with_check like '%auth.jwt()%user_metadata%' + or with_check like '%current_setting(%request.jwt.claims%)%user_metadata%' + )) +union all + +( +select + 'materialized_view_in_api' as "name!", + 'Materialized View in API' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects materialized views that are accessible over the Data APIs.' as "description!", + format( + 'Materialized view \`%s.%s\` is selectable by anon or authenticated roles', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'materialized view' + ) as "metadata!", + format( + 'materialized_view_in_api_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'm' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null) +union all + +( +select + 'foreign_table_in_api' as "name!", + 'Foreign Table in API' as "title!", + 'WARN' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects foreign tables that are accessible over APIs. Foreign tables do not respect row level security policies.' as "description!", + format( + 'Foreign table \`%s.%s\` is accessible over APIs', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'foreign table' + ) as "metadata!", + format( + 'foreign_table_in_api_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace + left join pg_catalog.pg_depend dep + on c.oid = dep.objid + and dep.deptype = 'e' +where + c.relkind = 'f' + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))) + and n.nspname not in ( + '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault' + ) + and dep.objid is null) +union all + +( +select + 'insecure_queue_exposed_in_api' as "name!", + 'Insecure Queue Exposed in API' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects cases where an insecure Queue is exposed over Data APIs' as "description!", + format( + 'Table \`%s.%s\` is public, but RLS has not been enabled.', + n.nspname, + c.relname + ) as "detail!", + 'https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c.relname, + 'type', 'table' + ) as "metadata!", + format( + 'rls_disabled_in_public_%s_%s', + n.nspname, + c.relname + ) as "cache_key!" +from + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on c.relnamespace = n.oid +where + c.relkind in ('r', 'I') -- regular or partitioned tables + and not c.relrowsecurity -- RLS is disabled + and ( + pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') + or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') + ) + and n.nspname = 'pgmq' -- tables in the pgmq schema + and c.relname like 'q_%' -- only queue tables + -- Constant requirements + and 'pgmq_public' = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))) +union all + +( +select + 'fkey_to_auth_unique' as "name!", + 'Foreign Key to Auth Unique Constraint' as "title!", + 'ERROR' as "level!", + 'EXTERNAL' as "facing!", + array['SECURITY'] as "categories!", + 'Detects user defined foreign keys to unique constraints in the auth schema.' as "description!", + format( + 'Table `%s`.`%s` has a foreign key `%s` referencing an auth unique constraint', + n.nspname, -- referencing schema + c_rel.relname, -- referencing table + c.conname -- fkey name + ) as "detail!", + 'Drop the foreign key constraint that references the auth schema.' as "remediation!", + jsonb_build_object( + 'schema', n.nspname, + 'name', c_rel.relname, + 'foreign_key', c.conname + ) as "metadata!", + format( + 'fkey_to_auth_unique_%s_%s_%s', + n.nspname, -- referencing schema + c_rel.relname, -- referencing table + c.conname + ) as "cache_key!" +from + pg_catalog.pg_constraint c + join pg_catalog.pg_class c_rel + on c.conrelid = c_rel.oid + join pg_catalog.pg_namespace n + on c_rel.relnamespace = n.oid + join pg_catalog.pg_class ref_rel + on c.confrelid = ref_rel.oid + join pg_catalog.pg_namespace cn + on ref_rel.relnamespace = cn.oid + join pg_catalog.pg_index i + on c.conindid = i.indexrelid +where c.contype = 'f' + and cn.nspname = 'auth' + and i.indisunique + and not i.indisprimary) diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index 627a7f8e6..2d7af9798 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -4,15 +4,30 @@ use std::collections::BTreeMap; use std::fs; use xtask::{glue::fs2, project_root}; -/// Generate splinter categories from the SQL file +/// Generate splinter categories from the SQL files (both generic and Supabase-specific) pub fn generate_splinter() -> Result<()> { - let sql_path = project_root().join("crates/pgls_splinter/vendor/splinter.sql"); - let sql_content = fs::read_to_string(&sql_path) - .with_context(|| format!("Failed to read SQL file at {sql_path:?}"))?; + let mut all_rules = BTreeMap::new(); + + // Process generic rules + let generic_sql_path = project_root().join("crates/pgls_splinter/vendor/splinter_generic.sql"); + if generic_sql_path.exists() { + let sql_content = fs::read_to_string(&generic_sql_path) + .with_context(|| format!("Failed to read SQL file at {generic_sql_path:?}"))?; + let rules = extract_rules_from_sql(&sql_content)?; + all_rules.extend(rules); + } - let rules = extract_rules_from_sql(&sql_content)?; + // Process Supabase-specific rules + let supabase_sql_path = + project_root().join("crates/pgls_splinter/vendor/splinter_supabase.sql"); + if supabase_sql_path.exists() { + let sql_content = fs::read_to_string(&supabase_sql_path) + .with_context(|| format!("Failed to read SQL file at {supabase_sql_path:?}"))?; + let rules = extract_rules_from_sql(&sql_content)?; + all_rules.extend(rules); + } - update_categories_file(rules)?; + update_categories_file(all_rules)?; Ok(()) } @@ -30,9 +45,8 @@ fn extract_rules_from_sql(content: &str) -> Result> { // Look for pattern: 'rule_name' as "name!", if line.contains(" as \"name!\"") { if let Some(name) = extract_string_literal(line) { - // Look ahead for categories and remediation URL + // Look ahead for categories let mut categories = None; - let mut remediation_url = None; for j in i..std::cmp::min(i + 30, lines.len()) { let next_line = lines[j].trim(); @@ -40,21 +54,10 @@ fn extract_rules_from_sql(content: &str) -> Result> { // Extract categories from pattern: array['CATEGORY'] as "categories!", if next_line.contains(" as \"categories!\"") { categories = extract_categories(next_line); - } - - if next_line.contains(" as \"remediation!\"") { - remediation_url = extract_string_literal(next_line); - } - - // Stop once we have both - if categories.is_some() && remediation_url.is_some() { - break; + break; // Stop once we have categories } } - let url = remediation_url - .with_context(|| format!("Failed to find remediation URL for rule '{name}'"))?; - let cats = categories .with_context(|| format!("Failed to find categories for rule '{name}'"))?; @@ -64,7 +67,6 @@ fn extract_rules_from_sql(content: &str) -> Result> { snake_case: name.clone(), camel_case: snake_to_camel_case(&name), categories: cats, - url, }, ); } @@ -80,7 +82,6 @@ fn extract_rules_from_sql(content: &str) -> Result> { snake_case: "unknown".to_string(), camel_case: "unknown".to_string(), categories: vec!["UNKNOWN".to_string()], - url: "https://pg-language-server.com/latest".to_string(), }, ); @@ -144,7 +145,37 @@ struct RuleInfo { snake_case: String, camel_case: String, categories: Vec, - url: String, +} + +/// Build remediation URL from rule name +/// Must match the logic in crates/pgls_splinter/src/convert.rs +fn build_remediation_url(name: &str) -> String { + let lint_id = match name { + "unindexed_foreign_keys" => "0001_unindexed_foreign_keys", + "auth_users_exposed" => "0002_auth_users_exposed", + "auth_rls_initplan" => "0003_auth_rls_initplan", + "no_primary_key" => "0004_no_primary_key", + "unused_index" => "0005_unused_index", + "multiple_permissive_policies" => "0006_multiple_permissive_policies", + "policy_exists_rls_disabled" => "0007_policy_exists_rls_disabled", + "rls_enabled_no_policy" => "0008_rls_enabled_no_policy", + "duplicate_index" => "0009_duplicate_index", + "security_definer_view" => "0010_security_definer_view", + "function_search_path_mutable" => "0011_function_search_path_mutable", + "rls_disabled_in_public" => "0013_rls_disabled_in_public", + "extension_in_public" => "0014_extension_in_public", + "rls_references_user_metadata" => "0015_rls_references_user_metadata", + "materialized_view_in_api" => "0016_materialized_view_in_api", + "foreign_table_in_api" => "0017_foreign_table_in_api", + "unsupported_reg_types" => "unsupported_reg_types", + "insecure_queue_exposed_in_api" => "0019_insecure_queue_exposed_in_api", + "table_bloat" => "0020_table_bloat", + "fkey_to_auth_unique" => "0021_fkey_to_auth_unique", + "extension_versions_outdated" => "0022_extension_versions_outdated", + _ => return "https://supabase.com/docs/guides/database/database-linter".to_string(), + }; + + format!("https://supabase.com/docs/guides/database/database-linter?lint={lint_id}") } /// Update the categories.rs file with splinter rules @@ -162,11 +193,12 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { // In practice, splinter rules have only one category rule.categories.iter().map(|category| { let group = category.to_lowercase(); + let url = build_remediation_url(&rule.snake_case); ( group.clone(), format!( " \"splinter/{}/{}\": \"{}\",", - group, rule.camel_case, rule.url + group, rule.camel_case, url ), ) }) From 154e3bbe73d63a6e8871dd8fa8d0c4077f693fa5 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Tue, 4 Nov 2025 10:02:24 +0100 Subject: [PATCH 14/17] fix: codegen --- ...5e4454b2c36eaf034657d5d2d95633fb85bdb.json | 74 +++++++++++++++++++ ...11046dc8b77d84c94314a0ed0716e5803df69.json | 74 +++++++++++++++++++ ...d5a53712d68afd273423f9310cd793586f532.json | 74 ------------------- .../src/categories.rs | 2 +- crates/pgls_splinter/src/convert.rs | 2 +- crates/pgls_splinter/tests/diagnostics.rs | 2 +- 6 files changed, 151 insertions(+), 77 deletions(-) create mode 100644 .sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json create mode 100644 .sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json delete mode 100644 .sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json diff --git a/.sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json b/.sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json new file mode 100644 index 000000000..459aa79a6 --- /dev/null +++ b/.sqlx/query-02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb.json @@ -0,0 +1,74 @@ +{ + "db_name": "PostgreSQL", + "query": "\n(\nwith foreign_keys as (\n select\n cl.relnamespace::regnamespace::text as schema_name,\n cl.relname as table_name,\n cl.oid as table_oid,\n ct.conname as fkey_name,\n ct.conkey as col_attnums\n from\n pg_catalog.pg_constraint ct\n join pg_catalog.pg_class cl -- fkey owning table\n on ct.conrelid = cl.oid\n left join pg_catalog.pg_depend d\n on d.objid = cl.oid\n and d.deptype = 'e'\n where\n ct.contype = 'f' -- foreign key constraints\n and d.objid is null -- exclude tables that are dependencies of extensions\n and cl.relnamespace::regnamespace::text not in (\n 'pg_catalog', 'information_schema', 'auth', 'storage', 'vault', 'extensions'\n )\n),\nindex_ as (\n select\n pi.indrelid as table_oid,\n indexrelid::regclass as index_,\n string_to_array(indkey::text, ' ')::smallint[] as col_attnums\n from\n pg_catalog.pg_index pi\n where\n indisvalid\n)\nselect\n 'unindexed_foreign_keys' as \"name!\",\n 'Unindexed foreign keys' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Identifies foreign key constraints without a covering index, which can impact database performance.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a foreign key \\`%s\\` without a covering index. This can lead to suboptimal query performance.',\n fk.schema_name,\n fk.table_name,\n fk.fkey_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys' as \"remediation!\",\n jsonb_build_object(\n 'schema', fk.schema_name,\n 'name', fk.table_name,\n 'type', 'table',\n 'fkey_name', fk.fkey_name,\n 'fkey_columns', fk.col_attnums\n ) as \"metadata!\",\n format('unindexed_foreign_keys_%s_%s_%s', fk.schema_name, fk.table_name, fk.fkey_name) as \"cache_key!\"\nfrom\n foreign_keys fk\n left join index_ idx\n on fk.table_oid = idx.table_oid\n and fk.col_attnums = idx.col_attnums[1:array_length(fk.col_attnums, 1)]\n left join pg_catalog.pg_depend dep\n on idx.table_oid = dep.objid\n and dep.deptype = 'e'\nwhere\n idx.index_ is null\n and fk.schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\norder by\n fk.schema_name,\n fk.table_name,\n fk.fkey_name)\nunion all\n\n(\nselect\n 'no_primary_key' as \"name!\",\n 'No Primary Key' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` does not have a primary key',\n pgns.nspname,\n pgc.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key' as \"remediation!\",\n jsonb_build_object(\n 'schema', pgns.nspname,\n 'name', pgc.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'no_primary_key_%s_%s',\n pgns.nspname,\n pgc.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class pgc\n join pg_catalog.pg_namespace pgns\n on pgns.oid = pgc.relnamespace\n left join pg_catalog.pg_index pgi\n on pgi.indrelid = pgc.oid\n left join pg_catalog.pg_depend dep\n on pgc.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n pgc.relkind = 'r' -- regular tables\n and pgns.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n pgc.oid,\n pgns.nspname,\n pgc.relname\nhaving\n max(coalesce(pgi.indisprimary, false)::int) = 0)\nunion all\n\n(\nselect\n 'unused_index' as \"name!\",\n 'Unused Index' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if an index has never been used and may be a candidate for removal.' as \"description!\",\n format(\n 'Index \\`%s\\` on table \\`%s.%s\\` has not been used',\n psui.indexrelname,\n psui.schemaname,\n psui.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', psui.schemaname,\n 'name', psui.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unused_index_%s_%s_%s',\n psui.schemaname,\n psui.relname,\n psui.indexrelname\n ) as \"cache_key!\"\n\nfrom\n pg_catalog.pg_stat_user_indexes psui\n join pg_catalog.pg_index pi\n on psui.indexrelid = pi.indexrelid\n left join pg_catalog.pg_depend dep\n on psui.relid = dep.objid\n and dep.deptype = 'e'\nwhere\n psui.idx_scan = 0\n and not pi.indisunique\n and not pi.indisprimary\n and dep.objid is null -- exclude tables owned by extensions\n and psui.schemaname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n\n(\nselect\n 'multiple_permissive_policies' as \"name!\",\n 'Multiple Permissive Policies' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if multiple permissive row level security policies are present on a table for the same \\`role\\` and \\`action\\` (e.g. insert). Multiple permissive policies are suboptimal for performance as each policy must be executed for every relevant query.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has multiple permissive policies for role \\`%s\\` for action \\`%s\\`. Policies include \\`%s\\`',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'multiple_permissive_policies_%s_%s_%s_%s',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_roles r\n on p.polroles @> array[r.oid]\n or p.polroles = array[0::oid]\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e',\n lateral (\n select x.cmd\n from unnest((\n select\n case p.polcmd\n when 'r' then array['SELECT']\n when 'a' then array['INSERT']\n when 'w' then array['UPDATE']\n when 'd' then array['DELETE']\n when '*' then array['SELECT', 'INSERT', 'UPDATE', 'DELETE']\n else array['ERROR']\n end as actions\n )) x(cmd)\n ) act(cmd)\nwhere\n c.relkind = 'r' -- regular tables\n and p.polpermissive -- policy is permissive\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and r.rolname not like 'pg_%'\n and r.rolname not like 'supabase%admin'\n and not r.rolbypassrls\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\nhaving\n count(1) > 1)\nunion all\n\n(\nselect\n 'policy_exists_rls_disabled' as \"name!\",\n 'Policy Exists RLS Disabled' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) policies have been created, but RLS has not been enabled for the underlying table.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS policies but RLS is not enabled on the table. Policies include %s.',\n n.nspname,\n c.relname,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'policy_exists_rls_disabled_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is disabled\n and not c.relrowsecurity\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n\n(\nselect\n 'rls_enabled_no_policy' as \"name!\",\n 'RLS Enabled No Policy' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has been enabled on a table but no RLS policies have been created.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS enabled, but no policies exist',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_enabled_no_policy_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n left join pg_catalog.pg_policy p\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is enabled\n and c.relrowsecurity\n and p.polname is null\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n\n(\nselect\n 'duplicate_index' as \"name!\",\n 'Duplicate Index' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects cases where two ore more identical indexes exist.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has identical indexes %s. Drop all except one of them',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', case\n when c.relkind = 'r' then 'table'\n when c.relkind = 'm' then 'materialized view'\n else 'ERROR'\n end,\n 'indexes', array_agg(pi.indexname order by pi.indexname)\n ) as \"metadata!\",\n format(\n 'duplicate_index_%s_%s_%s',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_indexes pi\n join pg_catalog.pg_namespace n\n on n.nspname = pi.schemaname\n join pg_catalog.pg_class c\n on pi.tablename = c.relname\n and n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind in ('r', 'm') -- tables and materialized views\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relkind,\n c.relname,\n replace(pi.indexdef, pi.indexname, '')\nhaving\n count(*) > 1)\nunion all\n\n(\nselect\n 'function_search_path_mutable' as \"name!\",\n 'Function Search Path Mutable' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects functions where the search_path parameter is not set.' as \"description!\",\n format(\n 'Function \\`%s.%s\\` has a role mutable search_path',\n n.nspname,\n p.proname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', p.proname,\n 'type', 'function'\n ) as \"metadata!\",\n format(\n 'function_search_path_mutable_%s_%s_%s',\n n.nspname,\n p.proname,\n md5(p.prosrc) -- required when function is polymorphic\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_proc p\n join pg_catalog.pg_namespace n\n on p.pronamespace = n.oid\n left join pg_catalog.pg_depend dep\n on p.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude functions owned by extensions\n -- Search path not set\n and not exists (\n select 1\n from unnest(coalesce(p.proconfig, '{}')) as config\n where config like 'search_path=%'\n ))\nunion all\n\n(\nselect\n 'extension_in_public' as \"name!\",\n 'Extension in Public' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions installed in the \\`public\\` schema.' as \"description!\",\n format(\n 'Extension \\`%s\\` is installed in the public schema. Move it to another schema.',\n pe.extname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', pe.extnamespace::regnamespace,\n 'name', pe.extname,\n 'type', 'extension'\n ) as \"metadata!\",\n format(\n 'extension_in_public_%s',\n pe.extname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_extension pe\nwhere\n -- plpgsql is installed by default in public and outside user control\n -- confirmed safe\n pe.extname not in ('plpgsql')\n -- Scoping this to public is not optimal. Ideally we would use the postgres\n -- search path. That currently isn't available via SQL. In other lints\n -- we have used has_schema_privilege('anon', 'extensions', 'USAGE') but that\n -- is not appropriate here as it would evaluate true for the extensions schema\n and pe.extnamespace::regnamespace::text = 'public')\nunion all\n\n(\nselect\n 'unsupported_reg_types' as \"name!\",\n 'Unsupported reg types' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Identifies columns using unsupported reg* types outside pg_catalog schema, which prevents database upgrades using pg_upgrade.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a column \\`%s\\` with unsupported reg* type \\`%s\\`.',\n n.nspname,\n c.relname,\n a.attname,\n t.typname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'column', a.attname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unsupported_reg_types_%s_%s_%s',\n n.nspname,\n c.relname,\n a.attname\n ) AS cache_key\nfrom\n pg_catalog.pg_attribute a\n join pg_catalog.pg_class c\n on a.attrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_type t\n on a.atttypid = t.oid\n join pg_catalog.pg_namespace tn\n on t.typnamespace = tn.oid\nwhere\n tn.nspname = 'pg_catalog'\n and t.typname in ('regcollation', 'regconfig', 'regdictionary', 'regnamespace', 'regoper', 'regoperator', 'regproc', 'regprocedure')\n and n.nspname not in ('pg_catalog', 'information_schema', 'pgsodium'))\nunion all\n\n(\nwith constants as (\n select current_setting('block_size')::numeric as bs, 23 as hdr, 4 as ma\n),\n\nbloat_info as (\n select\n ma,\n bs,\n schemaname,\n tablename,\n (datawidth + (hdr + ma - (case when hdr % ma = 0 then ma else hdr % ma end)))::numeric as datahdr,\n (maxfracsum * (nullhdr + ma - (case when nullhdr % ma = 0 then ma else nullhdr % ma end))) as nullhdr2\n from (\n select\n schemaname,\n tablename,\n hdr,\n ma,\n bs,\n sum((1 - null_frac) * avg_width) as datawidth,\n max(null_frac) as maxfracsum,\n hdr + (\n select 1 + count(*) / 8\n from pg_stats s2\n where\n null_frac <> 0\n and s2.schemaname = s.schemaname\n and s2.tablename = s.tablename\n ) as nullhdr\n from pg_stats s, constants\n group by 1, 2, 3, 4, 5\n ) as foo\n),\n\ntable_bloat as (\n select\n schemaname,\n tablename,\n cc.relpages,\n bs,\n ceil((cc.reltuples * ((datahdr + ma -\n (case when datahdr % ma = 0 then ma else datahdr % ma end)) + nullhdr2 + 4)) / (bs - 20::float)) as otta\n from\n bloat_info\n join pg_class cc\n on cc.relname = bloat_info.tablename\n join pg_namespace nn\n on cc.relnamespace = nn.oid\n and nn.nspname = bloat_info.schemaname\n and nn.nspname <> 'information_schema'\n where\n cc.relkind = 'r'\n and cc.relam = (select oid from pg_am where amname = 'heap')\n),\n\nbloat_data as (\n select\n 'table' as type,\n schemaname,\n tablename as object_name,\n round(case when otta = 0 then 0.0 else table_bloat.relpages / otta::numeric end, 1) as bloat,\n case when relpages < otta then 0 else (bs * (table_bloat.relpages - otta)::bigint)::bigint end as raw_waste\n from\n table_bloat\n)\n\nselect\n 'table_bloat' as \"name!\",\n 'Table Bloat' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table has excess bloat and may benefit from maintenance operations like vacuum full or cluster.' as \"description!\",\n format(\n 'Table `%s`.`%s` has excessive bloat',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"detail!\",\n 'Consider running vacuum full (WARNING: incurs downtime) and tweaking autovacuum settings to reduce bloat.' as \"remediation!\",\n jsonb_build_object(\n 'schema', bloat_data.schemaname,\n 'name', bloat_data.object_name,\n 'type', bloat_data.type\n ) as \"metadata!\",\n format(\n 'table_bloat_%s_%s',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"cache_key!\"\nfrom\n bloat_data\nwhere\n bloat > 70.0\n and raw_waste > (20 * 1024 * 1024) -- filter for waste > 200 MB\norder by\n schemaname,\n object_name)\nunion all\n\n(\nselect\n 'extension_versions_outdated' as \"name!\",\n 'Extension Versions Outdated' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions that are not using the default (recommended) version.' as \"description!\",\n format(\n 'Extension `%s` is using version `%s` but version `%s` is available. Using outdated extension versions may expose the database to security vulnerabilities.',\n ext.name,\n ext.installed_version,\n ext.default_version\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated' as \"remediation!\",\n jsonb_build_object(\n 'extension_name', ext.name,\n 'installed_version', ext.installed_version,\n 'default_version', ext.default_version\n ) as \"metadata!\",\n format(\n 'extension_versions_outdated_%s_%s',\n ext.name,\n ext.installed_version\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_available_extensions ext\njoin\n -- ignore versions not in pg_available_extension_versions\n -- e.g. residue of pg_upgrade\n pg_catalog.pg_available_extension_versions extv\n on extv.name = ext.name and extv.installed\nwhere\n ext.installed_version is not null\n and ext.default_version is not null\n and ext.installed_version != ext.default_version\norder by\n ext.name)", + "describe": { + "columns": [ + { + "ordinal": 0, + "name": "name!", + "type_info": "Text" + }, + { + "ordinal": 1, + "name": "title!", + "type_info": "Text" + }, + { + "ordinal": 2, + "name": "level!", + "type_info": "Text" + }, + { + "ordinal": 3, + "name": "facing!", + "type_info": "Text" + }, + { + "ordinal": 4, + "name": "categories!", + "type_info": "TextArray" + }, + { + "ordinal": 5, + "name": "description!", + "type_info": "Text" + }, + { + "ordinal": 6, + "name": "detail!", + "type_info": "Text" + }, + { + "ordinal": 7, + "name": "remediation!", + "type_info": "Text" + }, + { + "ordinal": 8, + "name": "metadata!", + "type_info": "Jsonb" + }, + { + "ordinal": 9, + "name": "cache_key!", + "type_info": "Text" + } + ], + "parameters": { + "Left": [] + }, + "nullable": [ + null, + null, + null, + null, + null, + null, + null, + null, + null, + null + ] + }, + "hash": "02927e584e85871ba6f84c58e8b5e4454b2c36eaf034657d5d2d95633fb85bdb" +} diff --git a/.sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json b/.sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json new file mode 100644 index 000000000..27081d1c4 --- /dev/null +++ b/.sqlx/query-425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69.json @@ -0,0 +1,74 @@ +{ + "db_name": "PostgreSQL", + "query": "\n(\nselect\n 'auth_users_exposed' as \"name!\",\n 'Exposed Auth Users' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects if auth.users is exposed to anon or authenticated roles via a view or materialized view in schemas exposed to PostgREST, potentially compromising user data security.' as \"description!\",\n format(\n 'View/Materialized View \"%s\" in the public schema may expose \\`auth.users\\` data to anon or authenticated roles.',\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view',\n 'exposed_to', array_remove(array_agg(DISTINCT case when pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') then 'anon' when pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') then 'authenticated' end), null)\n ) as \"metadata!\",\n format('auth_users_exposed_%s_%s', n.nspname, c.relname) as \"cache_key!\"\nfrom\n -- Identify the oid for auth.users\n pg_catalog.pg_class auth_users_pg_class\n join pg_catalog.pg_namespace auth_users_pg_namespace\n on auth_users_pg_class.relnamespace = auth_users_pg_namespace.oid\n and auth_users_pg_class.relname = 'users'\n and auth_users_pg_namespace.nspname = 'auth'\n -- Depends on auth.users\n join pg_catalog.pg_depend d\n on d.refobjid = auth_users_pg_class.oid\n join pg_catalog.pg_rewrite r\n on r.oid = d.objid\n join pg_catalog.pg_class c\n on c.oid = r.ev_class\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n join pg_catalog.pg_class pg_class_auth_users\n on d.refobjid = pg_class_auth_users.oid\nwhere\n d.deptype = 'n'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n -- Exclude self\n and c.relname <> '0002_auth_users_exposed'\n -- There are 3 insecure configurations\n and\n (\n -- Materialized views don't support RLS so this is insecure by default\n (c.relkind in ('m')) -- m for materialized view\n or\n -- Standard View, accessible to anon or authenticated that is security_definer\n (\n c.relkind = 'v' -- v for view\n -- Exclude security invoker views\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n )\n or\n -- Standard View, security invoker, but no RLS enabled on auth.users\n (\n c.relkind in ('v') -- v for view\n -- is security invoker\n and (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n and not pg_class_auth_users.relrowsecurity\n )\n )\ngroup by\n n.nspname,\n c.relname,\n c.oid)\nunion all\n\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n pc.relrowsecurity as is_rls_active,\n polname as policy_name,\n polpermissive as is_permissive, -- if not, then restrictive\n (select array_agg(r::regrole) from unnest(polroles) as x(r)) as roles,\n case polcmd\n when 'r' then 'SELECT'\n when 'a' then 'INSERT'\n when 'w' then 'UPDATE'\n when 'd' then 'DELETE'\n when '*' then 'ALL'\n end as command,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'auth_rls_initplan' as \"name!\",\n 'Auth RLS Initialization Plan' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if calls to \\`current_setting()\\` and \\`auth.()\\` in RLS policies are being unnecessarily re-evaluated for each row' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that re-evaluates current_setting() or auth.() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \\`auth.()\\` with \\`(select auth.())\\`. See [docs](https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select) for more info.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('auth_rls_init_plan_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n is_rls_active\n -- NOTE: does not include realtime in support of monitoring policies on realtime.messages\n and schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.uid()\n (\n qual like '%auth.uid()%'\n and lower(qual) not like '%select auth.uid()%'\n )\n or (\n qual like '%auth.jwt()%'\n and lower(qual) not like '%select auth.jwt()%'\n )\n or (\n qual like '%auth.role()%'\n and lower(qual) not like '%select auth.role()%'\n )\n or (\n qual like '%auth.email()%'\n and lower(qual) not like '%select auth.email()%'\n )\n or (\n qual like '%current\\_setting(%)%'\n and lower(qual) not like '%select current\\_setting(%)%'\n )\n or (\n with_check like '%auth.uid()%'\n and lower(with_check) not like '%select auth.uid()%'\n )\n or (\n with_check like '%auth.jwt()%'\n and lower(with_check) not like '%select auth.jwt()%'\n )\n or (\n with_check like '%auth.role()%'\n and lower(with_check) not like '%select auth.role()%'\n )\n or (\n with_check like '%auth.email()%'\n and lower(with_check) not like '%select auth.email()%'\n )\n or (\n with_check like '%current\\_setting(%)%'\n and lower(with_check) not like '%select current\\_setting(%)%'\n )\n ))\nunion all\n\n(\nselect\n 'security_definer_view' as \"name!\",\n 'Security Definer View' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects views defined with the SECURITY DEFINER property. These views enforce Postgres permissions and row level security policies (RLS) of the view creator, rather than that of the querying user' as \"description!\",\n format(\n 'View \\`%s.%s\\` is defined with the SECURITY DEFINER property',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view'\n ) as \"metadata!\",\n format(\n 'security_definer_view_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'v'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and substring(pg_catalog.version() from 'PostgreSQL ([0-9]+)') >= '15' -- security invoker was added in pg15\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude views owned by extensions\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n ))\nunion all\n\n(\nselect\n 'rls_disabled_in_public' as \"name!\",\n 'RLS Disabled in Public' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has not been enabled on tables in schemas exposed to PostgREST' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind = 'r' -- regular tables\n -- RLS is disabled\n and not c.relrowsecurity\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n polname as policy_name,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'rls_references_user_metadata' as \"name!\",\n 'RLS references user metadata' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects when Supabase Auth user_metadata is referenced insecurely in a row level security (RLS) policy.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that references Supabase Auth \\`user_metadata\\`. \\`user_metadata\\` is editable by end users and should never be used in a security context.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('rls_references_user_metadata_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.jwt() -> 'user_metadata'\n -- False positives are possible, but it isn't practical to string match\n -- If false positive rate is too high, this expression can iterate\n qual like '%auth.jwt()%user_metadata%'\n or qual like '%current_setting(%request.jwt.claims%)%user_metadata%'\n or with_check like '%auth.jwt()%user_metadata%'\n or with_check like '%current_setting(%request.jwt.claims%)%user_metadata%'\n ))\nunion all\n\n(\nselect\n 'materialized_view_in_api' as \"name!\",\n 'Materialized View in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects materialized views that are accessible over the Data APIs.' as \"description!\",\n format(\n 'Materialized view \\`%s.%s\\` is selectable by anon or authenticated roles',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'materialized view'\n ) as \"metadata!\",\n format(\n 'materialized_view_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'm'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n\n(\nselect\n 'foreign_table_in_api' as \"name!\",\n 'Foreign Table in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects foreign tables that are accessible over APIs. Foreign tables do not respect row level security policies.' as \"description!\",\n format(\n 'Foreign table \\`%s.%s\\` is accessible over APIs',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'foreign table'\n ) as \"metadata!\",\n format(\n 'foreign_table_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'f'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n\n(\nselect\n 'insecure_queue_exposed_in_api' as \"name!\",\n 'Insecure Queue Exposed in API' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where an insecure Queue is exposed over Data APIs' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind in ('r', 'I') -- regular or partitioned tables\n and not c.relrowsecurity -- RLS is disabled\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = 'pgmq' -- tables in the pgmq schema\n and c.relname like 'q_%' -- only queue tables\n -- Constant requirements\n and 'pgmq_public' = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))))\nunion all\n\n(\nselect\n 'fkey_to_auth_unique' as \"name!\",\n 'Foreign Key to Auth Unique Constraint' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects user defined foreign keys to unique constraints in the auth schema.' as \"description!\",\n format(\n 'Table `%s`.`%s` has a foreign key `%s` referencing an auth unique constraint',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname -- fkey name\n ) as \"detail!\",\n 'Drop the foreign key constraint that references the auth schema.' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c_rel.relname,\n 'foreign_key', c.conname\n ) as \"metadata!\",\n format(\n 'fkey_to_auth_unique_%s_%s_%s',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_constraint c\n join pg_catalog.pg_class c_rel\n on c.conrelid = c_rel.oid\n join pg_catalog.pg_namespace n\n on c_rel.relnamespace = n.oid\n join pg_catalog.pg_class ref_rel\n on c.confrelid = ref_rel.oid\n join pg_catalog.pg_namespace cn\n on ref_rel.relnamespace = cn.oid\n join pg_catalog.pg_index i\n on c.conindid = i.indexrelid\nwhere c.contype = 'f'\n and cn.nspname = 'auth'\n and i.indisunique\n and not i.indisprimary)\n", + "describe": { + "columns": [ + { + "ordinal": 0, + "name": "name!", + "type_info": "Text" + }, + { + "ordinal": 1, + "name": "title!", + "type_info": "Text" + }, + { + "ordinal": 2, + "name": "level!", + "type_info": "Text" + }, + { + "ordinal": 3, + "name": "facing!", + "type_info": "Text" + }, + { + "ordinal": 4, + "name": "categories!", + "type_info": "TextArray" + }, + { + "ordinal": 5, + "name": "description!", + "type_info": "Text" + }, + { + "ordinal": 6, + "name": "detail!", + "type_info": "Text" + }, + { + "ordinal": 7, + "name": "remediation!", + "type_info": "Text" + }, + { + "ordinal": 8, + "name": "metadata!", + "type_info": "Jsonb" + }, + { + "ordinal": 9, + "name": "cache_key!", + "type_info": "Text" + } + ], + "parameters": { + "Left": [] + }, + "nullable": [ + null, + null, + null, + null, + null, + null, + null, + null, + null, + null + ] + }, + "hash": "425fc6118e76cea42cf256b3b0f11046dc8b77d84c94314a0ed0716e5803df69" +} diff --git a/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json b/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json deleted file mode 100644 index c460f458d..000000000 --- a/.sqlx/query-b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532.json +++ /dev/null @@ -1,74 +0,0 @@ -{ - "db_name": "PostgreSQL", - "query": "\n(\nwith foreign_keys as (\n select\n cl.relnamespace::regnamespace::text as schema_name,\n cl.relname as table_name,\n cl.oid as table_oid,\n ct.conname as fkey_name,\n ct.conkey as col_attnums\n from\n pg_catalog.pg_constraint ct\n join pg_catalog.pg_class cl -- fkey owning table\n on ct.conrelid = cl.oid\n left join pg_catalog.pg_depend d\n on d.objid = cl.oid\n and d.deptype = 'e'\n where\n ct.contype = 'f' -- foreign key constraints\n and d.objid is null -- exclude tables that are dependencies of extensions\n and cl.relnamespace::regnamespace::text not in (\n 'pg_catalog', 'information_schema', 'auth', 'storage', 'vault', 'extensions'\n )\n),\nindex_ as (\n select\n pi.indrelid as table_oid,\n indexrelid::regclass as index_,\n string_to_array(indkey::text, ' ')::smallint[] as col_attnums\n from\n pg_catalog.pg_index pi\n where\n indisvalid\n)\nselect\n 'unindexed_foreign_keys' as \"name!\",\n 'Unindexed foreign keys' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Identifies foreign key constraints without a covering index, which can impact database performance.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a foreign key \\`%s\\` without a covering index. This can lead to suboptimal query performance.',\n fk.schema_name,\n fk.table_name,\n fk.fkey_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys' as \"remediation!\",\n jsonb_build_object(\n 'schema', fk.schema_name,\n 'name', fk.table_name,\n 'type', 'table',\n 'fkey_name', fk.fkey_name,\n 'fkey_columns', fk.col_attnums\n ) as \"metadata!\",\n format('unindexed_foreign_keys_%s_%s_%s', fk.schema_name, fk.table_name, fk.fkey_name) as \"cache_key!\"\nfrom\n foreign_keys fk\n left join index_ idx\n on fk.table_oid = idx.table_oid\n and fk.col_attnums = idx.col_attnums[1:array_length(fk.col_attnums, 1)]\n left join pg_catalog.pg_depend dep\n on idx.table_oid = dep.objid\n and dep.deptype = 'e'\nwhere\n idx.index_ is null\n and fk.schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\norder by\n fk.schema_name,\n fk.table_name,\n fk.fkey_name)\nunion all\n(\nselect\n 'auth_users_exposed' as \"name!\",\n 'Exposed Auth Users' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects if auth.users is exposed to anon or authenticated roles via a view or materialized view in schemas exposed to PostgREST, potentially compromising user data security.' as \"description!\",\n format(\n 'View/Materialized View \"%s\" in the public schema may expose \\`auth.users\\` data to anon or authenticated roles.',\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view',\n 'exposed_to', array_remove(array_agg(DISTINCT case when pg_catalog.has_table_privilege('anon', c.oid, 'SELECT') then 'anon' when pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT') then 'authenticated' end), null)\n ) as \"metadata!\",\n format('auth_users_exposed_%s_%s', n.nspname, c.relname) as \"cache_key!\"\nfrom\n -- Identify the oid for auth.users\n pg_catalog.pg_class auth_users_pg_class\n join pg_catalog.pg_namespace auth_users_pg_namespace\n on auth_users_pg_class.relnamespace = auth_users_pg_namespace.oid\n and auth_users_pg_class.relname = 'users'\n and auth_users_pg_namespace.nspname = 'auth'\n -- Depends on auth.users\n join pg_catalog.pg_depend d\n on d.refobjid = auth_users_pg_class.oid\n join pg_catalog.pg_rewrite r\n on r.oid = d.objid\n join pg_catalog.pg_class c\n on c.oid = r.ev_class\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n join pg_catalog.pg_class pg_class_auth_users\n on d.refobjid = pg_class_auth_users.oid\nwhere\n d.deptype = 'n'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n -- Exclude self\n and c.relname <> '0002_auth_users_exposed'\n -- There are 3 insecure configurations\n and\n (\n -- Materialized views don't support RLS so this is insecure by default\n (c.relkind in ('m')) -- m for materialized view\n or\n -- Standard View, accessible to anon or authenticated that is security_definer\n (\n c.relkind = 'v' -- v for view\n -- Exclude security invoker views\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n )\n or\n -- Standard View, security invoker, but no RLS enabled on auth.users\n (\n c.relkind in ('v') -- v for view\n -- is security invoker\n and (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n )\n and not pg_class_auth_users.relrowsecurity\n )\n )\ngroup by\n n.nspname,\n c.relname,\n c.oid)\nunion all\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n pc.relrowsecurity as is_rls_active,\n polname as policy_name,\n polpermissive as is_permissive, -- if not, then restrictive\n (select array_agg(r::regrole) from unnest(polroles) as x(r)) as roles,\n case polcmd\n when 'r' then 'SELECT'\n when 'a' then 'INSERT'\n when 'w' then 'UPDATE'\n when 'd' then 'DELETE'\n when '*' then 'ALL'\n end as command,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'auth_rls_initplan' as \"name!\",\n 'Auth RLS Initialization Plan' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if calls to \\`current_setting()\\` and \\`auth.()\\` in RLS policies are being unnecessarily re-evaluated for each row' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that re-evaluates current_setting() or auth.() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \\`auth.()\\` with \\`(select auth.())\\`. See [docs](https://supabase.com/docs/guides/database/postgres/row-level-security#call-functions-with-select) for more info.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('auth_rls_init_plan_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n is_rls_active\n -- NOTE: does not include realtime in support of monitoring policies on realtime.messages\n and schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.uid()\n (\n qual like '%auth.uid()%'\n and lower(qual) not like '%select auth.uid()%'\n )\n or (\n qual like '%auth.jwt()%'\n and lower(qual) not like '%select auth.jwt()%'\n )\n or (\n qual like '%auth.role()%'\n and lower(qual) not like '%select auth.role()%'\n )\n or (\n qual like '%auth.email()%'\n and lower(qual) not like '%select auth.email()%'\n )\n or (\n qual like '%current\\_setting(%)%'\n and lower(qual) not like '%select current\\_setting(%)%'\n )\n or (\n with_check like '%auth.uid()%'\n and lower(with_check) not like '%select auth.uid()%'\n )\n or (\n with_check like '%auth.jwt()%'\n and lower(with_check) not like '%select auth.jwt()%'\n )\n or (\n with_check like '%auth.role()%'\n and lower(with_check) not like '%select auth.role()%'\n )\n or (\n with_check like '%auth.email()%'\n and lower(with_check) not like '%select auth.email()%'\n )\n or (\n with_check like '%current\\_setting(%)%'\n and lower(with_check) not like '%select current\\_setting(%)%'\n )\n ))\nunion all\n(\nselect\n 'no_primary_key' as \"name!\",\n 'No Primary Key' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` does not have a primary key',\n pgns.nspname,\n pgc.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key' as \"remediation!\",\n jsonb_build_object(\n 'schema', pgns.nspname,\n 'name', pgc.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'no_primary_key_%s_%s',\n pgns.nspname,\n pgc.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class pgc\n join pg_catalog.pg_namespace pgns\n on pgns.oid = pgc.relnamespace\n left join pg_catalog.pg_index pgi\n on pgi.indrelid = pgc.oid\n left join pg_catalog.pg_depend dep\n on pgc.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n pgc.relkind = 'r' -- regular tables\n and pgns.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n pgc.oid,\n pgns.nspname,\n pgc.relname\nhaving\n max(coalesce(pgi.indisprimary, false)::int) = 0)\nunion all\n(\nselect\n 'unused_index' as \"name!\",\n 'Unused Index' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if an index has never been used and may be a candidate for removal.' as \"description!\",\n format(\n 'Index \\`%s\\` on table \\`%s.%s\\` has not been used',\n psui.indexrelname,\n psui.schemaname,\n psui.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', psui.schemaname,\n 'name', psui.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unused_index_%s_%s_%s',\n psui.schemaname,\n psui.relname,\n psui.indexrelname\n ) as \"cache_key!\"\n\nfrom\n pg_catalog.pg_stat_user_indexes psui\n join pg_catalog.pg_index pi\n on psui.indexrelid = pi.indexrelid\n left join pg_catalog.pg_depend dep\n on psui.relid = dep.objid\n and dep.deptype = 'e'\nwhere\n psui.idx_scan = 0\n and not pi.indisunique\n and not pi.indisprimary\n and dep.objid is null -- exclude tables owned by extensions\n and psui.schemaname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n(\nselect\n 'multiple_permissive_policies' as \"name!\",\n 'Multiple Permissive Policies' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if multiple permissive row level security policies are present on a table for the same \\`role\\` and \\`action\\` (e.g. insert). Multiple permissive policies are suboptimal for performance as each policy must be executed for every relevant query.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has multiple permissive policies for role \\`%s\\` for action \\`%s\\`. Policies include \\`%s\\`',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'multiple_permissive_policies_%s_%s_%s_%s',\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_roles r\n on p.polroles @> array[r.oid]\n or p.polroles = array[0::oid]\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e',\n lateral (\n select x.cmd\n from unnest((\n select\n case p.polcmd\n when 'r' then array['SELECT']\n when 'a' then array['INSERT']\n when 'w' then array['UPDATE']\n when 'd' then array['DELETE']\n when '*' then array['SELECT', 'INSERT', 'UPDATE', 'DELETE']\n else array['ERROR']\n end as actions\n )) x(cmd)\n ) act(cmd)\nwhere\n c.relkind = 'r' -- regular tables\n and p.polpermissive -- policy is permissive\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and r.rolname not like 'pg_%'\n and r.rolname not like 'supabase%admin'\n and not r.rolbypassrls\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname,\n r.rolname,\n act.cmd\nhaving\n count(1) > 1)\nunion all\n(\nselect\n 'policy_exists_rls_disabled' as \"name!\",\n 'Policy Exists RLS Disabled' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) policies have been created, but RLS has not been enabled for the underlying table.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS policies but RLS is not enabled on the table. Policies include %s.',\n n.nspname,\n c.relname,\n array_agg(p.polname order by p.polname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'policy_exists_rls_disabled_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_policy p\n join pg_catalog.pg_class c\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is disabled\n and not c.relrowsecurity\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n(\nselect\n 'rls_enabled_no_policy' as \"name!\",\n 'RLS Enabled No Policy' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has been enabled on a table but no RLS policies have been created.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has RLS enabled, but no policies exist',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_enabled_no_policy_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n left join pg_catalog.pg_policy p\n on p.polrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'r' -- regular tables\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n -- RLS is enabled\n and c.relrowsecurity\n and p.polname is null\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relname)\nunion all\n(\nselect\n 'duplicate_index' as \"name!\",\n 'Duplicate Index' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects cases where two ore more identical indexes exist.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has identical indexes %s. Drop all except one of them',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', case\n when c.relkind = 'r' then 'table'\n when c.relkind = 'm' then 'materialized view'\n else 'ERROR'\n end,\n 'indexes', array_agg(pi.indexname order by pi.indexname)\n ) as \"metadata!\",\n format(\n 'duplicate_index_%s_%s_%s',\n n.nspname,\n c.relname,\n array_agg(pi.indexname order by pi.indexname)\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_indexes pi\n join pg_catalog.pg_namespace n\n on n.nspname = pi.schemaname\n join pg_catalog.pg_class c\n on pi.tablename = c.relname\n and n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind in ('r', 'm') -- tables and materialized views\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude tables owned by extensions\ngroup by\n n.nspname,\n c.relkind,\n c.relname,\n replace(pi.indexdef, pi.indexname, '')\nhaving\n count(*) > 1)\nunion all\n(\nselect\n 'security_definer_view' as \"name!\",\n 'Security Definer View' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects views defined with the SECURITY DEFINER property. These views enforce Postgres permissions and row level security policies (RLS) of the view creator, rather than that of the querying user' as \"description!\",\n format(\n 'View \\`%s.%s\\` is defined with the SECURITY DEFINER property',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'view'\n ) as \"metadata!\",\n format(\n 'security_definer_view_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'v'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and substring(pg_catalog.version() from 'PostgreSQL ([0-9]+)') >= '15' -- security invoker was added in pg15\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude views owned by extensions\n and not (\n lower(coalesce(c.reloptions::text,'{}'))::text[]\n && array[\n 'security_invoker=1',\n 'security_invoker=true',\n 'security_invoker=yes',\n 'security_invoker=on'\n ]\n ))\nunion all\n(\nselect\n 'function_search_path_mutable' as \"name!\",\n 'Function Search Path Mutable' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects functions where the search_path parameter is not set.' as \"description!\",\n format(\n 'Function \\`%s.%s\\` has a role mutable search_path',\n n.nspname,\n p.proname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', p.proname,\n 'type', 'function'\n ) as \"metadata!\",\n format(\n 'function_search_path_mutable_%s_%s_%s',\n n.nspname,\n p.proname,\n md5(p.prosrc) -- required when function is polymorphic\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_proc p\n join pg_catalog.pg_namespace n\n on p.pronamespace = n.oid\n left join pg_catalog.pg_depend dep\n on p.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null -- exclude functions owned by extensions\n -- Search path not set\n and not exists (\n select 1\n from unnest(coalesce(p.proconfig, '{}')) as config\n where config like 'search_path=%'\n ))\nunion all\n(\nselect\n 'rls_disabled_in_public' as \"name!\",\n 'RLS Disabled in Public' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where row level security (RLS) has not been enabled on tables in schemas exposed to PostgREST' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind = 'r' -- regular tables\n -- RLS is disabled\n and not c.relrowsecurity\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))\nunion all\n(\nselect\n 'extension_in_public' as \"name!\",\n 'Extension in Public' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions installed in the \\`public\\` schema.' as \"description!\",\n format(\n 'Extension \\`%s\\` is installed in the public schema. Move it to another schema.',\n pe.extname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public' as \"remediation!\",\n jsonb_build_object(\n 'schema', pe.extnamespace::regnamespace,\n 'name', pe.extname,\n 'type', 'extension'\n ) as \"metadata!\",\n format(\n 'extension_in_public_%s',\n pe.extname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_extension pe\nwhere\n -- plpgsql is installed by default in public and outside user control\n -- confirmed safe\n pe.extname not in ('plpgsql')\n -- Scoping this to public is not optimal. Ideally we would use the postgres\n -- search path. That currently isn't available via SQL. In other lints\n -- we have used has_schema_privilege('anon', 'extensions', 'USAGE') but that\n -- is not appropriate here as it would evaluate true for the extensions schema\n and pe.extnamespace::regnamespace::text = 'public')\nunion all\n(\nwith policies as (\n select\n nsp.nspname as schema_name,\n pb.tablename as table_name,\n polname as policy_name,\n qual,\n with_check\n from\n pg_catalog.pg_policy pa\n join pg_catalog.pg_class pc\n on pa.polrelid = pc.oid\n join pg_catalog.pg_namespace nsp\n on pc.relnamespace = nsp.oid\n join pg_catalog.pg_policies pb\n on pc.relname = pb.tablename\n and nsp.nspname = pb.schemaname\n and pa.polname = pb.policyname\n)\nselect\n 'rls_references_user_metadata' as \"name!\",\n 'RLS references user metadata' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects when Supabase Auth user_metadata is referenced insecurely in a row level security (RLS) policy.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a row level security policy \\`%s\\` that references Supabase Auth \\`user_metadata\\`. \\`user_metadata\\` is editable by end users and should never be used in a security context.',\n schema_name,\n table_name,\n policy_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata' as \"remediation!\",\n jsonb_build_object(\n 'schema', schema_name,\n 'name', table_name,\n 'type', 'table'\n ) as \"metadata!\",\n format('rls_references_user_metadata_%s_%s_%s', schema_name, table_name, policy_name) as \"cache_key!\"\nfrom\n policies\nwhere\n schema_name not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and (\n -- Example: auth.jwt() -> 'user_metadata'\n -- False positives are possible, but it isn't practical to string match\n -- If false positive rate is too high, this expression can iterate\n qual like '%auth.jwt()%user_metadata%'\n or qual like '%current_setting(%request.jwt.claims%)%user_metadata%'\n or with_check like '%auth.jwt()%user_metadata%'\n or with_check like '%current_setting(%request.jwt.claims%)%user_metadata%'\n ))\nunion all\n(\nselect\n 'materialized_view_in_api' as \"name!\",\n 'Materialized View in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects materialized views that are accessible over the Data APIs.' as \"description!\",\n format(\n 'Materialized view \\`%s.%s\\` is selectable by anon or authenticated roles',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'materialized view'\n ) as \"metadata!\",\n format(\n 'materialized_view_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'm'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n(\nselect\n 'foreign_table_in_api' as \"name!\",\n 'Foreign Table in API' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects foreign tables that are accessible over APIs. Foreign tables do not respect row level security policies.' as \"description!\",\n format(\n 'Foreign table \\`%s.%s\\` is accessible over APIs',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'foreign table'\n ) as \"metadata!\",\n format(\n 'foreign_table_in_api_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on n.oid = c.relnamespace\n left join pg_catalog.pg_depend dep\n on c.oid = dep.objid\n and dep.deptype = 'e'\nwhere\n c.relkind = 'f'\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ',')))))\n and n.nspname not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgmq', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n )\n and dep.objid is null)\nunion all\n(\nselect\n 'unsupported_reg_types' as \"name!\",\n 'Unsupported reg types' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Identifies columns using unsupported reg* types outside pg_catalog schema, which prevents database upgrades using pg_upgrade.' as \"description!\",\n format(\n 'Table \\`%s.%s\\` has a column \\`%s\\` with unsupported reg* type \\`%s\\`.',\n n.nspname,\n c.relname,\n a.attname,\n t.typname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'column', a.attname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'unsupported_reg_types_%s_%s_%s',\n n.nspname,\n c.relname,\n a.attname\n ) AS cache_key\nfrom\n pg_catalog.pg_attribute a\n join pg_catalog.pg_class c\n on a.attrelid = c.oid\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\n join pg_catalog.pg_type t\n on a.atttypid = t.oid\n join pg_catalog.pg_namespace tn\n on t.typnamespace = tn.oid\nwhere\n tn.nspname = 'pg_catalog'\n and t.typname in ('regcollation', 'regconfig', 'regdictionary', 'regnamespace', 'regoper', 'regoperator', 'regproc', 'regprocedure')\n and n.nspname not in ('pg_catalog', 'information_schema', 'pgsodium'))\nunion all\n(\nselect\n 'insecure_queue_exposed_in_api' as \"name!\",\n 'Insecure Queue Exposed in API' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects cases where an insecure Queue is exposed over Data APIs' as \"description!\",\n format(\n 'Table \\`%s.%s\\` is public, but RLS has not been enabled.',\n n.nspname,\n c.relname\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c.relname,\n 'type', 'table'\n ) as \"metadata!\",\n format(\n 'rls_disabled_in_public_%s_%s',\n n.nspname,\n c.relname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_class c\n join pg_catalog.pg_namespace n\n on c.relnamespace = n.oid\nwhere\n c.relkind in ('r', 'I') -- regular or partitioned tables\n and not c.relrowsecurity -- RLS is disabled\n and (\n pg_catalog.has_table_privilege('anon', c.oid, 'SELECT')\n or pg_catalog.has_table_privilege('authenticated', c.oid, 'SELECT')\n )\n and n.nspname = 'pgmq' -- tables in the pgmq schema\n and c.relname like 'q_%' -- only queue tables\n -- Constant requirements\n and 'pgmq_public' = any(array(select trim(unnest(string_to_array(current_setting('pgrst.db_schemas', 't'), ','))))))\nunion all\n(\nwith constants as (\n select current_setting('block_size')::numeric as bs, 23 as hdr, 4 as ma\n),\n\nbloat_info as (\n select\n ma,\n bs,\n schemaname,\n tablename,\n (datawidth + (hdr + ma - (case when hdr % ma = 0 then ma else hdr % ma end)))::numeric as datahdr,\n (maxfracsum * (nullhdr + ma - (case when nullhdr % ma = 0 then ma else nullhdr % ma end))) as nullhdr2\n from (\n select\n schemaname,\n tablename,\n hdr,\n ma,\n bs,\n sum((1 - null_frac) * avg_width) as datawidth,\n max(null_frac) as maxfracsum,\n hdr + (\n select 1 + count(*) / 8\n from pg_stats s2\n where\n null_frac <> 0\n and s2.schemaname = s.schemaname\n and s2.tablename = s.tablename\n ) as nullhdr\n from pg_stats s, constants\n group by 1, 2, 3, 4, 5\n ) as foo\n),\n\ntable_bloat as (\n select\n schemaname,\n tablename,\n cc.relpages,\n bs,\n ceil((cc.reltuples * ((datahdr + ma -\n (case when datahdr % ma = 0 then ma else datahdr % ma end)) + nullhdr2 + 4)) / (bs - 20::float)) as otta\n from\n bloat_info\n join pg_class cc\n on cc.relname = bloat_info.tablename\n join pg_namespace nn\n on cc.relnamespace = nn.oid\n and nn.nspname = bloat_info.schemaname\n and nn.nspname <> 'information_schema'\n where\n cc.relkind = 'r'\n and cc.relam = (select oid from pg_am where amname = 'heap')\n),\n\nbloat_data as (\n select\n 'table' as type,\n schemaname,\n tablename as object_name,\n round(case when otta = 0 then 0.0 else table_bloat.relpages / otta::numeric end, 1) as bloat,\n case when relpages < otta then 0 else (bs * (table_bloat.relpages - otta)::bigint)::bigint end as raw_waste\n from\n table_bloat\n)\n\nselect\n 'table_bloat' as \"name!\",\n 'Table Bloat' as \"title!\",\n 'INFO' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['PERFORMANCE'] as \"categories!\",\n 'Detects if a table has excess bloat and may benefit from maintenance operations like vacuum full or cluster.' as \"description!\",\n format(\n 'Table `%s`.`%s` has excessive bloat',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat' as \"remediation!\",\n jsonb_build_object(\n 'schema', bloat_data.schemaname,\n 'name', bloat_data.object_name,\n 'type', bloat_data.type\n ) as \"metadata!\",\n format(\n 'table_bloat_%s_%s',\n bloat_data.schemaname,\n bloat_data.object_name\n ) as \"cache_key!\"\nfrom\n bloat_data\nwhere\n bloat > 70.0\n and raw_waste > (20 * 1024 * 1024) -- filter for waste > 200 MB\norder by\n schemaname,\n object_name)\nunion all\n(\nselect\n 'fkey_to_auth_unique' as \"name!\",\n 'Foreign Key to Auth Unique Constraint' as \"title!\",\n 'ERROR' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects user defined foreign keys to unique constraints in the auth schema.' as \"description!\",\n format(\n 'Table `%s`.`%s` has a foreign key `%s` referencing an auth unique constraint',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname -- fkey name\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique' as \"remediation!\",\n jsonb_build_object(\n 'schema', n.nspname,\n 'name', c_rel.relname,\n 'foreign_key', c.conname\n ) as \"metadata!\",\n format(\n 'fkey_to_auth_unique_%s_%s_%s',\n n.nspname, -- referencing schema\n c_rel.relname, -- referencing table\n c.conname\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_constraint c\n join pg_catalog.pg_class c_rel\n on c.conrelid = c_rel.oid\n join pg_catalog.pg_namespace n\n on c_rel.relnamespace = n.oid\n join pg_catalog.pg_class ref_rel\n on c.confrelid = ref_rel.oid\n join pg_catalog.pg_namespace cn\n on ref_rel.relnamespace = cn.oid\n join pg_catalog.pg_index i\n on c.conindid = i.indexrelid\nwhere c.contype = 'f'\n and cn.nspname = 'auth'\n and i.indisunique\n and not i.indisprimary)\nunion all\n(\nselect\n 'extension_versions_outdated' as \"name!\",\n 'Extension Versions Outdated' as \"title!\",\n 'WARN' as \"level!\",\n 'EXTERNAL' as \"facing!\",\n array['SECURITY'] as \"categories!\",\n 'Detects extensions that are not using the default (recommended) version.' as \"description!\",\n format(\n 'Extension `%s` is using version `%s` but version `%s` is available. Using outdated extension versions may expose the database to security vulnerabilities.',\n ext.name,\n ext.installed_version,\n ext.default_version\n ) as \"detail!\",\n 'https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated' as \"remediation!\",\n jsonb_build_object(\n 'extension_name', ext.name,\n 'installed_version', ext.installed_version,\n 'default_version', ext.default_version\n ) as \"metadata!\",\n format(\n 'extension_versions_outdated_%s_%s',\n ext.name,\n ext.installed_version\n ) as \"cache_key!\"\nfrom\n pg_catalog.pg_available_extensions ext\njoin\n -- ignore versions not in pg_available_extension_versions\n -- e.g. residue of pg_upgrade\n pg_catalog.pg_available_extension_versions extv\n on extv.name = ext.name and extv.installed\nwhere\n ext.installed_version is not null\n and ext.default_version is not null\n and ext.installed_version != ext.default_version\norder by\n ext.name)", - "describe": { - "columns": [ - { - "ordinal": 0, - "name": "name!", - "type_info": "Text" - }, - { - "ordinal": 1, - "name": "title!", - "type_info": "Text" - }, - { - "ordinal": 2, - "name": "level!", - "type_info": "Text" - }, - { - "ordinal": 3, - "name": "facing!", - "type_info": "Text" - }, - { - "ordinal": 4, - "name": "categories!", - "type_info": "TextArray" - }, - { - "ordinal": 5, - "name": "description!", - "type_info": "Text" - }, - { - "ordinal": 6, - "name": "detail!", - "type_info": "Text" - }, - { - "ordinal": 7, - "name": "remediation!", - "type_info": "Text" - }, - { - "ordinal": 8, - "name": "metadata!", - "type_info": "Jsonb" - }, - { - "ordinal": 9, - "name": "cache_key!", - "type_info": "Text" - } - ], - "parameters": { - "Left": [] - }, - "nullable": [ - null, - null, - null, - null, - null, - null, - null, - null, - null, - null - ] - }, - "hash": "b869d517301aaf69d382f092c09d5a53712d68afd273423f9310cd793586f532" -} diff --git a/crates/pgls_diagnostics_categories/src/categories.rs b/crates/pgls_diagnostics_categories/src/categories.rs index ba0e4c65d..a9c257d03 100644 --- a/crates/pgls_diagnostics_categories/src/categories.rs +++ b/crates/pgls_diagnostics_categories/src/categories.rs @@ -69,7 +69,7 @@ define_categories! { "splinter/security/rlsReferencesUserMetadata": "https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata", "splinter/security/securityDefinerView": "https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view", "splinter/security/unsupportedRegTypes": "https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types", - "splinter/unknown/unknown": "https://pg-language-server.com/latest", + "splinter/unknown/unknown": "https://supabase.com/docs/guides/database/database-linter", // splinter rules end ; // General categories diff --git a/crates/pgls_splinter/src/convert.rs b/crates/pgls_splinter/src/convert.rs index 11d01f7e1..a296fda0b 100644 --- a/crates/pgls_splinter/src/convert.rs +++ b/crates/pgls_splinter/src/convert.rs @@ -1,4 +1,4 @@ -use pgls_diagnostics::{category, Category, Severity}; +use pgls_diagnostics::{Category, Severity, category}; use serde_json::Value; use crate::{SplinterAdvices, SplinterDiagnostic, SplinterQueryResult}; diff --git a/crates/pgls_splinter/tests/diagnostics.rs b/crates/pgls_splinter/tests/diagnostics.rs index 53713989a..ecd84860f 100644 --- a/crates/pgls_splinter/tests/diagnostics.rs +++ b/crates/pgls_splinter/tests/diagnostics.rs @@ -1,6 +1,6 @@ use pgls_console::fmt::{Formatter, HTML}; use pgls_diagnostics::{Diagnostic, LogCategory, Visit}; -use pgls_splinter::{run_splinter, SplinterParams}; +use pgls_splinter::{SplinterParams, run_splinter}; use sqlx::PgPool; use std::fmt::Write; use std::io; From 6babd1ae2eda0018a20fa15ba077d91ae51563b5 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Tue, 4 Nov 2025 10:21:43 +0100 Subject: [PATCH 15/17] fix: resolve clippy warnings and improve code quality - Remove empty line after outer attribute in pgls_diagnostics - Replace useless format! with .to_string() in pgls_splinter - Refactor loops to use .enumerate() and slice indexing in xtask_codegen - Add clippy and git commit guidelines to AGENTS.md --- AGENTS.md | 6 ++++++ crates/pgls_diagnostics/src/serde.rs | 1 - crates/pgls_splinter/src/convert.rs | 2 +- xtask/codegen/src/generate_splinter.rs | 11 ++++------- 4 files changed, 11 insertions(+), 9 deletions(-) diff --git a/AGENTS.md b/AGENTS.md index 73fe17907..64d876302 100644 --- a/AGENTS.md +++ b/AGENTS.md @@ -144,6 +144,12 @@ cargo insta review ## Development Notes +### Code Quality Guidelines +**IMPORTANT**: Always run `cargo clippy --all-targets --all-features` and fix all warnings after making code changes. Clippy warnings must be resolved before committing code to maintain code quality standards. + +### Git Commit and PR Guidelines +**IMPORTANT**: NEVER add "Claude" or any AI assistant name to commit messages or pull request descriptions. Commits and PRs should appear as authored by the human developer only. + ### Code Generation Many parser structures are generated from PostgreSQL's protobuf definitions using procedural macros in `pgls_query_macros`. Run `just gen-lint` after modifying analyzer rules or configurations. diff --git a/crates/pgls_diagnostics/src/serde.rs b/crates/pgls_diagnostics/src/serde.rs index 7e0e7a098..bcc85a3e1 100644 --- a/crates/pgls_diagnostics/src/serde.rs +++ b/crates/pgls_diagnostics/src/serde.rs @@ -164,7 +164,6 @@ impl From> for Location { #[serde(rename_all = "camelCase")] #[cfg_attr(feature = "schema", derive(schemars::JsonSchema))] #[cfg_attr(test, derive(Eq, PartialEq))] - struct Advices { advices: Vec, } diff --git a/crates/pgls_splinter/src/convert.rs b/crates/pgls_splinter/src/convert.rs index a296fda0b..32c6f5d97 100644 --- a/crates/pgls_splinter/src/convert.rs +++ b/crates/pgls_splinter/src/convert.rs @@ -60,7 +60,7 @@ fn build_remediation_url(name: &str) -> String { "table_bloat" => "0020_table_bloat", "fkey_to_auth_unique" => "0021_fkey_to_auth_unique", "extension_versions_outdated" => "0022_extension_versions_outdated", - _ => return format!("https://supabase.com/docs/guides/database/database-linter"), + _ => return "https://supabase.com/docs/guides/database/database-linter".to_string(), }; format!("https://supabase.com/docs/guides/database/database-linter?lint={lint_id}") diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index 2d7af9798..5dd5341c1 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -37,10 +37,9 @@ fn extract_rules_from_sql(content: &str) -> Result> { let mut rules = BTreeMap::new(); let lines: Vec<&str> = content.lines().collect(); - let mut i = 0; - while i < lines.len() { - let line = lines[i].trim(); + for (i, line) in lines.iter().enumerate() { + let line = line.trim(); // Look for pattern: 'rule_name' as "name!", if line.contains(" as \"name!\"") { @@ -48,8 +47,8 @@ fn extract_rules_from_sql(content: &str) -> Result> { // Look ahead for categories let mut categories = None; - for j in i..std::cmp::min(i + 30, lines.len()) { - let next_line = lines[j].trim(); + for next_line in lines[i..].iter().take(30) { + let next_line = next_line.trim(); // Extract categories from pattern: array['CATEGORY'] as "categories!", if next_line.contains(" as \"categories!\"") { @@ -71,8 +70,6 @@ fn extract_rules_from_sql(content: &str) -> Result> { ); } } - - i += 1; } // Add the "unknown" fallback rule From 600f273307f52eef50d4629bed7cfd34c0c39416 Mon Sep 17 00:00:00 2001 From: psteinroe Date: Fri, 7 Nov 2025 08:31:08 +0100 Subject: [PATCH 16/17] refactor: no manual url building --- .../src/categories.rs | 4 +- crates/pgls_splinter/TODO.md | 1 - crates/pgls_splinter/src/convert.rs | 35 +---------- crates/pgls_splinter/src/diagnostics.rs | 6 +- .../tests/snapshots/multiple_issues.snap | 4 +- .../tests/snapshots/no_primary_key.snap | 2 +- .../snapshots/policy_exists_rls_disabled.snap | 2 +- .../snapshots/unindexed_foreign_key.snap | 2 +- xtask/codegen/src/generate_splinter.rs | 63 +++++++++---------- 9 files changed, 41 insertions(+), 78 deletions(-) delete mode 100644 crates/pgls_splinter/TODO.md diff --git a/crates/pgls_diagnostics_categories/src/categories.rs b/crates/pgls_diagnostics_categories/src/categories.rs index a9c257d03..11c17d7c0 100644 --- a/crates/pgls_diagnostics_categories/src/categories.rs +++ b/crates/pgls_diagnostics_categories/src/categories.rs @@ -52,13 +52,13 @@ define_categories! { "splinter/performance/duplicateIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index", "splinter/performance/multiplePermissivePolicies": "https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies", "splinter/performance/noPrimaryKey": "https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key", - "splinter/performance/tableBloat": "https://supabase.com/docs/guides/database/database-linter?lint=0020_table_bloat", + "splinter/performance/tableBloat": "https://supabase.com/docs/guides/database/database-linter", "splinter/performance/unindexedForeignKeys": "https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys", "splinter/performance/unusedIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index", "splinter/security/authUsersExposed": "https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed", "splinter/security/extensionInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public", "splinter/security/extensionVersionsOutdated": "https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated", - "splinter/security/fkeyToAuthUnique": "https://supabase.com/docs/guides/database/database-linter?lint=0021_fkey_to_auth_unique", + "splinter/security/fkeyToAuthUnique": "https://supabase.com/docs/guides/database/database-linter", "splinter/security/foreignTableInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api", "splinter/security/functionSearchPathMutable": "https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable", "splinter/security/insecureQueueExposedInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api", diff --git a/crates/pgls_splinter/TODO.md b/crates/pgls_splinter/TODO.md deleted file mode 100644 index 25f48ac22..000000000 --- a/crates/pgls_splinter/TODO.md +++ /dev/null @@ -1 +0,0 @@ -- implement ignore / include and config. try to refactor existing analyser infrastructure to be re-used. diff --git a/crates/pgls_splinter/src/convert.rs b/crates/pgls_splinter/src/convert.rs index 32c6f5d97..926de1d40 100644 --- a/crates/pgls_splinter/src/convert.rs +++ b/crates/pgls_splinter/src/convert.rs @@ -27,45 +27,13 @@ impl From for SplinterDiagnostic { schema, object_name, object_type, - remediation_url: build_remediation_url(&result.name), + remediation: result.remediation, additional_metadata, }, } } } -/// Build remediation URL from rule name -/// Maps rule names to their Supabase linter documentation -fn build_remediation_url(name: &str) -> String { - // Map rule names to their lint IDs - let lint_id = match name { - "unindexed_foreign_keys" => "0001_unindexed_foreign_keys", - "auth_users_exposed" => "0002_auth_users_exposed", - "auth_rls_initplan" => "0003_auth_rls_initplan", - "no_primary_key" => "0004_no_primary_key", - "unused_index" => "0005_unused_index", - "multiple_permissive_policies" => "0006_multiple_permissive_policies", - "policy_exists_rls_disabled" => "0007_policy_exists_rls_disabled", - "rls_enabled_no_policy" => "0008_rls_enabled_no_policy", - "duplicate_index" => "0009_duplicate_index", - "security_definer_view" => "0010_security_definer_view", - "function_search_path_mutable" => "0011_function_search_path_mutable", - "rls_disabled_in_public" => "0013_rls_disabled_in_public", - "extension_in_public" => "0014_extension_in_public", - "rls_references_user_metadata" => "0015_rls_references_user_metadata", - "materialized_view_in_api" => "0016_materialized_view_in_api", - "foreign_table_in_api" => "0017_foreign_table_in_api", - "unsupported_reg_types" => "unsupported_reg_types", - "insecure_queue_exposed_in_api" => "0019_insecure_queue_exposed_in_api", - "table_bloat" => "0020_table_bloat", - "fkey_to_auth_unique" => "0021_fkey_to_auth_unique", - "extension_versions_outdated" => "0022_extension_versions_outdated", - _ => return "https://supabase.com/docs/guides/database/database-linter".to_string(), - }; - - format!("https://supabase.com/docs/guides/database/database-linter?lint={lint_id}") -} - /// Parse severity level from the query result fn parse_severity(level: &str) -> Severity { match level { @@ -79,6 +47,7 @@ fn parse_severity(level: &str) -> Severity { /// Convert rule name and group to a Category /// Note: Rule names use snake_case, but categories use camelCase fn rule_name_to_category(name: &str, group: &str) -> &'static Category { + // we cannot use convert_case here because category! macro requires a string literal match (group, name) { ("performance", "unindexed_foreign_keys") => { category!("splinter/performance/unindexedForeignKeys") diff --git a/crates/pgls_splinter/src/diagnostics.rs b/crates/pgls_splinter/src/diagnostics.rs index c88ab945d..7ff6ca942 100644 --- a/crates/pgls_splinter/src/diagnostics.rs +++ b/crates/pgls_splinter/src/diagnostics.rs @@ -41,7 +41,7 @@ pub struct SplinterAdvices { pub object_type: Option, /// URL to documentation/remediation guide - pub remediation_url: String, + pub remediation: String, /// Additional rule-specific metadata (e.g., fkey_name, column, indexes) /// This contains fields that don't fit into the common structure @@ -70,10 +70,10 @@ impl Advices for SplinterAdvices { } } - // Show remediation URL + // Show remediation visitor.record_log( LogCategory::Info, - &format!("Documentation: {}", &self.remediation_url), + &format!("Remediation: {}", &self.remediation), )?; Ok(()) diff --git a/crates/pgls_splinter/tests/snapshots/multiple_issues.snap b/crates/pgls_splinter/tests/snapshots/multiple_issues.snap index 7cce55230..1a3a05b33 100644 --- a/crates/pgls_splinter/tests/snapshots/multiple_issues.snap +++ b/crates/pgls_splinter/tests/snapshots/multiple_issues.snap @@ -10,7 +10,7 @@ Advices: Identifies foreign key constraints without a covering index, which can impact database performance. [Info] table: public.child_table {"fkey_name":"child_table_parent_id_fkey","fkey_columns":[2]} -[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys +[Info] Remediation: https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys --- @@ -20,4 +20,4 @@ Message: Table \`public.no_pk_table\` does not have a primary key Advices: Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale. [Info] table: public.no_pk_table -[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key +[Info] Remediation: https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key diff --git a/crates/pgls_splinter/tests/snapshots/no_primary_key.snap b/crates/pgls_splinter/tests/snapshots/no_primary_key.snap index d6bc383ee..80495b6ca 100644 --- a/crates/pgls_splinter/tests/snapshots/no_primary_key.snap +++ b/crates/pgls_splinter/tests/snapshots/no_primary_key.snap @@ -9,4 +9,4 @@ Message: Table \`public.articles\` does not have a primary key Advices: Detects if a table does not have a primary key. Tables without a primary key can be inefficient to interact with at scale. [Info] table: public.articles -[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key +[Info] Remediation: https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key diff --git a/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap b/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap index 2603ed7e0..a5c83a521 100644 --- a/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap +++ b/crates/pgls_splinter/tests/snapshots/policy_exists_rls_disabled.snap @@ -9,4 +9,4 @@ Message: Table \`public.documents\` has RLS policies but RLS is not enabled on t Advices: Detects cases where row level security (RLS) policies have been created, but RLS has not been enabled for the underlying table. [Info] table: public.documents -[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled +[Info] Remediation: https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled diff --git a/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap b/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap index ef31777b9..d6c4b7239 100644 --- a/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap +++ b/crates/pgls_splinter/tests/snapshots/unindexed_foreign_key.snap @@ -10,4 +10,4 @@ Advices: Identifies foreign key constraints without a covering index, which can impact database performance. [Info] table: public.posts {"fkey_name":"posts_user_id_fkey","fkey_columns":[2]} -[Info] Documentation: https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys +[Info] Remediation: https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index 5dd5341c1..7eee1eb46 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -44,8 +44,9 @@ fn extract_rules_from_sql(content: &str) -> Result> { // Look for pattern: 'rule_name' as "name!", if line.contains(" as \"name!\"") { if let Some(name) = extract_string_literal(line) { - // Look ahead for categories + // Look ahead for categories and remediation URL let mut categories = None; + let mut remediation_url = None; for next_line in lines[i..].iter().take(30) { let next_line = next_line.trim(); @@ -53,7 +54,16 @@ fn extract_rules_from_sql(content: &str) -> Result> { // Extract categories from pattern: array['CATEGORY'] as "categories!", if next_line.contains(" as \"categories!\"") { categories = extract_categories(next_line); - break; // Stop once we have categories + } + + // Extract remediation URL from pattern: 'url' as "remediation!", + if next_line.contains(" as \"remediation!\"") { + remediation_url = extract_string_literal(next_line); + } + + // Stop once we have both + if categories.is_some() && remediation_url.is_some() { + break; } } @@ -66,6 +76,7 @@ fn extract_rules_from_sql(content: &str) -> Result> { snake_case: name.clone(), camel_case: snake_to_camel_case(&name), categories: cats, + url: remediation_url, }, ); } @@ -79,6 +90,7 @@ fn extract_rules_from_sql(content: &str) -> Result> { snake_case: "unknown".to_string(), camel_case: "unknown".to_string(), categories: vec!["UNKNOWN".to_string()], + url: None, }, ); @@ -137,42 +149,17 @@ fn snake_to_camel_case(s: &str) -> String { Case::Camel.convert(s) } +/// Check if a string is a valid URL (simple check for http/https) +fn is_valid_url(s: &str) -> bool { + s.starts_with("http://") || s.starts_with("https://") +} + struct RuleInfo { #[allow(dead_code)] snake_case: String, camel_case: String, categories: Vec, -} - -/// Build remediation URL from rule name -/// Must match the logic in crates/pgls_splinter/src/convert.rs -fn build_remediation_url(name: &str) -> String { - let lint_id = match name { - "unindexed_foreign_keys" => "0001_unindexed_foreign_keys", - "auth_users_exposed" => "0002_auth_users_exposed", - "auth_rls_initplan" => "0003_auth_rls_initplan", - "no_primary_key" => "0004_no_primary_key", - "unused_index" => "0005_unused_index", - "multiple_permissive_policies" => "0006_multiple_permissive_policies", - "policy_exists_rls_disabled" => "0007_policy_exists_rls_disabled", - "rls_enabled_no_policy" => "0008_rls_enabled_no_policy", - "duplicate_index" => "0009_duplicate_index", - "security_definer_view" => "0010_security_definer_view", - "function_search_path_mutable" => "0011_function_search_path_mutable", - "rls_disabled_in_public" => "0013_rls_disabled_in_public", - "extension_in_public" => "0014_extension_in_public", - "rls_references_user_metadata" => "0015_rls_references_user_metadata", - "materialized_view_in_api" => "0016_materialized_view_in_api", - "foreign_table_in_api" => "0017_foreign_table_in_api", - "unsupported_reg_types" => "unsupported_reg_types", - "insecure_queue_exposed_in_api" => "0019_insecure_queue_exposed_in_api", - "table_bloat" => "0020_table_bloat", - "fkey_to_auth_unique" => "0021_fkey_to_auth_unique", - "extension_versions_outdated" => "0022_extension_versions_outdated", - _ => return "https://supabase.com/docs/guides/database/database-linter".to_string(), - }; - - format!("https://supabase.com/docs/guides/database/database-linter?lint={lint_id}") + url: Option, } /// Update the categories.rs file with splinter rules @@ -190,7 +177,15 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { // In practice, splinter rules have only one category rule.categories.iter().map(|category| { let group = category.to_lowercase(); - let url = build_remediation_url(&rule.snake_case); + + // Use extracted URL if it's a valid URL, otherwise fallback to default + let url = rule + .url + .as_ref() + .filter(|u| is_valid_url(u)) + .map(|u| u.as_str()) + .unwrap_or("https://supabase.com/docs/guides/database/database-linter"); + ( group.clone(), format!( From 3469bbf9b4eff3c77c8d635d65c7de292398144c Mon Sep 17 00:00:00 2001 From: psteinroe Date: Fri, 7 Nov 2025 15:08:40 +0100 Subject: [PATCH 17/17] progress --- .../src/categories.rs | 44 ++++++++-------- crates/pgls_splinter/build.rs | 52 ++++++++++++++++++- xtask/codegen/src/generate_splinter.rs | 13 +++-- 3 files changed, 82 insertions(+), 27 deletions(-) diff --git a/crates/pgls_diagnostics_categories/src/categories.rs b/crates/pgls_diagnostics_categories/src/categories.rs index 11c17d7c0..38517401e 100644 --- a/crates/pgls_diagnostics_categories/src/categories.rs +++ b/crates/pgls_diagnostics_categories/src/categories.rs @@ -48,28 +48,28 @@ define_categories! { "lint/safety/transactionNesting": "https://pg-language-server.com/latest/rules/transaction-nesting", // end lint rules // splinter rules start - "splinter/performance/authRlsInitplan": "https://supabase.com/docs/guides/database/database-linter?lint=0003_auth_rls_initplan", - "splinter/performance/duplicateIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0009_duplicate_index", - "splinter/performance/multiplePermissivePolicies": "https://supabase.com/docs/guides/database/database-linter?lint=0006_multiple_permissive_policies", - "splinter/performance/noPrimaryKey": "https://supabase.com/docs/guides/database/database-linter?lint=0004_no_primary_key", - "splinter/performance/tableBloat": "https://supabase.com/docs/guides/database/database-linter", - "splinter/performance/unindexedForeignKeys": "https://supabase.com/docs/guides/database/database-linter?lint=0001_unindexed_foreign_keys", - "splinter/performance/unusedIndex": "https://supabase.com/docs/guides/database/database-linter?lint=0005_unused_index", - "splinter/security/authUsersExposed": "https://supabase.com/docs/guides/database/database-linter?lint=0002_auth_users_exposed", - "splinter/security/extensionInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0014_extension_in_public", - "splinter/security/extensionVersionsOutdated": "https://supabase.com/docs/guides/database/database-linter?lint=0022_extension_versions_outdated", - "splinter/security/fkeyToAuthUnique": "https://supabase.com/docs/guides/database/database-linter", - "splinter/security/foreignTableInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0017_foreign_table_in_api", - "splinter/security/functionSearchPathMutable": "https://supabase.com/docs/guides/database/database-linter?lint=0011_function_search_path_mutable", - "splinter/security/insecureQueueExposedInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0019_insecure_queue_exposed_in_api", - "splinter/security/materializedViewInApi": "https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api", - "splinter/security/policyExistsRlsDisabled": "https://supabase.com/docs/guides/database/database-linter?lint=0007_policy_exists_rls_disabled", - "splinter/security/rlsDisabledInPublic": "https://supabase.com/docs/guides/database/database-linter?lint=0013_rls_disabled_in_public", - "splinter/security/rlsEnabledNoPolicy": "https://supabase.com/docs/guides/database/database-linter?lint=0008_rls_enabled_no_policy", - "splinter/security/rlsReferencesUserMetadata": "https://supabase.com/docs/guides/database/database-linter?lint=0015_rls_references_user_metadata", - "splinter/security/securityDefinerView": "https://supabase.com/docs/guides/database/database-linter?lint=0010_security_definer_view", - "splinter/security/unsupportedRegTypes": "https://supabase.com/docs/guides/database/database-linter?lint=unsupported_reg_types", - "splinter/unknown/unknown": "https://supabase.com/docs/guides/database/database-linter", + "splinter/performance/authRlsInitplan": "https://supabase.com/docs/guides/database/database-advisors?lint=0003_auth_rls_initplan", + "splinter/performance/duplicateIndex": "https://supabase.com/docs/guides/database/database-advisors?lint=0009_duplicate_index", + "splinter/performance/multiplePermissivePolicies": "https://supabase.com/docs/guides/database/database-advisors?lint=0006_multiple_permissive_policies", + "splinter/performance/noPrimaryKey": "https://supabase.com/docs/guides/database/database-advisors?lint=0004_no_primary_key", + "splinter/performance/tableBloat": "https://supabase.com/docs/guides/database/database-advisors", + "splinter/performance/unindexedForeignKeys": "https://supabase.com/docs/guides/database/database-advisors?lint=0001_unindexed_foreign_keys", + "splinter/performance/unusedIndex": "https://supabase.com/docs/guides/database/database-advisors?lint=0005_unused_index", + "splinter/security/authUsersExposed": "https://supabase.com/docs/guides/database/database-advisors?lint=0002_auth_users_exposed", + "splinter/security/extensionInPublic": "https://supabase.com/docs/guides/database/database-advisors?lint=0014_extension_in_public", + "splinter/security/extensionVersionsOutdated": "https://supabase.com/docs/guides/database/database-advisors?lint=0022_extension_versions_outdated", + "splinter/security/fkeyToAuthUnique": "https://supabase.com/docs/guides/database/database-advisors", + "splinter/security/foreignTableInApi": "https://supabase.com/docs/guides/database/database-advisors?lint=0017_foreign_table_in_api", + "splinter/security/functionSearchPathMutable": "https://supabase.com/docs/guides/database/database-advisors?lint=0011_function_search_path_mutable", + "splinter/security/insecureQueueExposedInApi": "https://supabase.com/docs/guides/database/database-advisors?lint=0019_insecure_queue_exposed_in_api", + "splinter/security/materializedViewInApi": "https://supabase.com/docs/guides/database/database-advisors?lint=0016_materialized_view_in_api", + "splinter/security/policyExistsRlsDisabled": "https://supabase.com/docs/guides/database/database-advisors?lint=0007_policy_exists_rls_disabled", + "splinter/security/rlsDisabledInPublic": "https://supabase.com/docs/guides/database/database-advisors?lint=0013_rls_disabled_in_public", + "splinter/security/rlsEnabledNoPolicy": "https://supabase.com/docs/guides/database/database-advisors?lint=0008_rls_enabled_no_policy", + "splinter/security/rlsReferencesUserMetadata": "https://supabase.com/docs/guides/database/database-advisors?lint=0015_rls_references_user_metadata", + "splinter/security/securityDefinerView": "https://supabase.com/docs/guides/database/database-advisors?lint=0010_security_definer_view", + "splinter/security/unsupportedRegTypes": "https://supabase.com/docs/guides/database/database-advisors?lint=unsupported_reg_types", + "splinter/unknown/unknown": "https://supabase.com/docs/guides/database/database-advisors", // splinter rules end ; // General categories diff --git a/crates/pgls_splinter/build.rs b/crates/pgls_splinter/build.rs index be09b9e6d..d7d55e693 100644 --- a/crates/pgls_splinter/build.rs +++ b/crates/pgls_splinter/build.rs @@ -5,6 +5,22 @@ use std::path::Path; // Update this commit SHA to pull in a new version of splinter.sql const SPLINTER_COMMIT_SHA: &str = "27ea2ece65464213e466cd969cc61b6940d16219"; +// Rules that work on any PostgreSQL database +const GENERIC_RULES: &[&str] = &[ + "unindexed_foreign_keys", + "no_primary_key", + "unused_index", + "multiple_permissive_policies", + "policy_exists_rls_disabled", + "rls_enabled_no_policy", + "duplicate_index", + "extension_in_public", + "table_bloat", + "extension_versions_outdated", + "function_search_path_mutable", + "unsupported_reg_types", +]; + // Rules that require Supabase-specific infrastructure (auth schema, anon/authenticated roles, pgrst.db_schemas) const SUPABASE_ONLY_RULES: &[&str] = &[ "auth_users_exposed", @@ -76,7 +92,7 @@ fn download_and_process_sql(generic_dest: &Path, supabase_dest: &Path) { // Add "!" suffix to column aliases for sqlx non-null checking processed_content = add_not_null_markers(&processed_content); - // Split into generic and Supabase-specific queries + // Split into generic and Supabase-specific queries (validates categorization) let (generic_queries, supabase_queries) = split_queries(&processed_content); // Write to destination files @@ -129,6 +145,21 @@ fn add_not_null_markers(content: &str) -> String { result } +/// Extract rule name from a query fragment +fn extract_rule_name_from_query(query: &str) -> String { + // Look for pattern 'rule_name' as "name!" + for line in query.lines() { + if line.contains(" as \"name!\"") { + if let Some(start) = line.rfind('\'') { + if let Some(prev_quote) = line[..start].rfind('\'') { + return line[prev_quote + 1..start].to_string(); + } + } + } + } + "unknown".to_string() +} + fn split_queries(content: &str) -> (String, String) { // Split the union all queries based on rule names let queries: Vec<&str> = content.split("union all").collect(); @@ -142,10 +173,27 @@ fn split_queries(content: &str) -> (String, String) { .iter() .any(|rule| query.contains(&format!("'{rule}' as \"name!\""))); + let is_generic = GENERIC_RULES + .iter() + .any(|rule| query.contains(&format!("'{rule}' as \"name!\""))); + if is_supabase { supabase_queries.push(query); - } else { + } else if is_generic { generic_queries.push(query); + } else { + // Extract rule name for better error message + let rule_name = extract_rule_name_from_query(query); + panic!( + "Found unknown Splinter rule that is not categorized: {rule_name:?}\n\ + Please add this rule to either GENERIC_RULES or SUPABASE_ONLY_RULES in build.rs.\n\ + \n\ + Guidelines:\n\ + - GENERIC_RULES: Rules that work on any PostgreSQL database\n\ + - SUPABASE_ONLY_RULES: Rules that require Supabase infrastructure (auth schema, roles, pgrst.db_schemas)\n\ + \n\ + This prevents new Supabase-specific rules from breaking linting on non-Supabase databases." + ); } } diff --git a/xtask/codegen/src/generate_splinter.rs b/xtask/codegen/src/generate_splinter.rs index 7eee1eb46..b44a66aed 100644 --- a/xtask/codegen/src/generate_splinter.rs +++ b/xtask/codegen/src/generate_splinter.rs @@ -70,13 +70,20 @@ fn extract_rules_from_sql(content: &str) -> Result> { let cats = categories .with_context(|| format!("Failed to find categories for rule '{name}'"))?; + // Convert old database-linter URLs to database-advisors + let updated_url = remediation_url + .map(|url| url.replace("/database-linter", "/database-advisors")) + .or(Some( + "https://supabase.com/docs/guides/database/database-advisors".to_string(), + )); + rules.insert( name.clone(), RuleInfo { snake_case: name.clone(), camel_case: snake_to_camel_case(&name), categories: cats, - url: remediation_url, + url: updated_url, }, ); } @@ -90,7 +97,7 @@ fn extract_rules_from_sql(content: &str) -> Result> { snake_case: "unknown".to_string(), camel_case: "unknown".to_string(), categories: vec!["UNKNOWN".to_string()], - url: None, + url: Some("https://supabase.com/docs/guides/database/database-advisors".to_string()), }, ); @@ -184,7 +191,7 @@ fn update_categories_file(rules: BTreeMap) -> Result<()> { .as_ref() .filter(|u| is_valid_url(u)) .map(|u| u.as_str()) - .unwrap_or("https://supabase.com/docs/guides/database/database-linter"); + .unwrap_or("https://supabase.com/docs/guides/database/database-advisors"); ( group.clone(),