Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Lint 0016: materialized view in API #68

Merged
merged 5 commits into from
May 8, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
28 changes: 28 additions & 0 deletions docs/0016_materialized_view_in_api.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
Level: WARN

### Rationale

Materialized views in Postgres can present a security risk if they are accessible to API roles `anon` and `authenticated`. Unlike regular views, materialized views can not be configured to respect Row Level Security (RLS) policies of the underlying tables they are built upon, nor can they cannot be secured with RLS directly. Therefore, if materialized views are accessible over APIs, all rows are always visible, which may not be intended.

### The Risk of Materialized Views Accessible by Anon or Authenticated Roles

If materialized views are exposed in APIs and accessible by the `anon` or `authenticated` roles, API users bypass any Row-Level Security (RLS) policies implemented on the underlying tables. This can lead to unintended exposure of sensitive data as all users will be able to select all rows of data from the materialized views.

### How to Resolve

To mitigate the risk it is recommended to revoke `select` access from API roles `anon` and `authenticated`.

```sql
revoke select on public.some_mat_view from public, anon, authenticated;
```

Note that the `public` role is a role that sets default permissions for all other roles. If the `public` role allows access by default (as it does in the `public` schema) you must also revoke `select` accesss from it.

You can test if your permissions update worked sucessfully by running

```sql
select pg_catalog.has_table_privilege('anon', 'public.some_mat_view'::regclass::oid, 'select')
-- Should return: 'false'
```

Substituting in the appropriate role and view name.
42 changes: 42 additions & 0 deletions lints/0016_materialized_view_in_api.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
create view lint."0016_materialized_view_in_api" as

select
'materialized_view_in_api' as name,
'WARN' as level,
'EXTERNAL' as facing,
array['SECURITY'] as categories,
'Detects materialized views that are potentially accessible over 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', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'
)
and dep.objid is null;
3 changes: 2 additions & 1 deletion splinter.json
Original file line number Diff line number Diff line change
Expand Up @@ -12,5 +12,6 @@
"0011_function_search_path_mutable": "(\nselect\n 'function_search_path_mutable' as name,\n 'WARN' as level,\n 'EXTERNAL' as facing,\n array['SECURITY'] as categories,\n 'Detects functions with a mutable search_path parameter which could fail to execute successfully for some roles.' 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', '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 to ''\n and not coalesce(p.proconfig, '{}') && array['search_path=\"\"'])",
"0013_rls_disabled_in_public": "(\nselect\n 'rls_disabled_in_public' as name,\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 a table in the \\`public\\` schema.' 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 not in (\n '_timescaledb_cache', '_timescaledb_catalog', '_timescaledb_config', '_timescaledb_internal', 'auth', 'cron', 'extensions', 'graphql', 'graphql_public', 'information_schema', 'net', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'\n ))",
"0014_extension_in_public": "(\nselect\n 'extension_in_public' as name,\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')",
"0015_rls_references_user_metadata": "(\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 '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', '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 ))"
"0015_rls_references_user_metadata": "(\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 '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', '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 ))",
"0016_materialized_view_in_api": "(\nselect\n 'materialized_view_in_api' as name,\n 'WARN' as level,\n 'EXTERNAL' as facing,\n array['SECURITY'] as categories,\n 'Detects materialized views that are potentially accessible over 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', '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)"
}
44 changes: 43 additions & 1 deletion splinter.sql
Original file line number Diff line number Diff line change
Expand Up @@ -766,4 +766,46 @@ where
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,
'WARN' as level,
'EXTERNAL' as facing,
array['SECURITY'] as categories,
'Detects materialized views that are potentially accessible over 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', 'pgroonga', 'pgsodium', 'pgsodium_masks', 'pgtle', 'pgbouncer', 'pg_catalog', 'pgtle', 'realtime', 'repack', 'storage', 'supabase_functions', 'supabase_migrations', 'tiger', 'topology', 'vault'
)
and dep.objid is null)
26 changes: 26 additions & 0 deletions test/expected/0016_materialized_view_in_api.out
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
begin;
set local search_path = '';
set local pgrst.db_schemas = 'public';
-- 0 issues
select * from lint."0016_materialized_view_in_api";
name | level | facing | categories | description | detail | remediation | metadata | cache_key
------+-------+--------+------------+-------------+--------+-------------+----------+-----------
(0 rows)

create materialized view public.my_view as select 1;
-- 1 issue
select * from lint."0016_materialized_view_in_api";
name | level | facing | categories | description | detail | remediation | metadata | cache_key
--------------------------+-------+----------+------------+-----------------------------------------------------------------------+-----------------------------------------------------------------------------------+----------------------------------------------------------------------------------------------+----------------------------------------------------------------------+-----------------------------------------
materialized_view_in_api | WARN | EXTERNAL | {SECURITY} | Detects materialized views that are potentially accessible over APIs. | Materialized view \`public.my_view\` is selectable by anon or authenticated roles | https://supabase.com/docs/guides/database/database-linter?lint=0016_materialized_view_in_api | {"name": "my_view", "type": "materialized view", "schema": "public"} | materialized_view_in_api_public_my_view
(1 row)

-- Resolve the issue with permissions
revoke select on public.my_view from anon, authenticated, public;
-- 0 issues
select * from lint."0016_materialized_view_in_api";
name | level | facing | categories | description | detail | remediation | metadata | cache_key
------+-------+--------+------------+-------------+--------+-------------+----------+-----------
(0 rows)

rollback;
4 changes: 3 additions & 1 deletion test/expected/queries_are_unionable.out
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,9 @@ begin;
union all
select * from lint."0014_extension_in_public"
union all
select * from lint."0015_rls_references_user_metadata";
select * from lint."0015_rls_references_user_metadata"
union all
select * from lint."0016_materialized_view_in_api";
name | level | facing | categories | description | detail | remediation | metadata | cache_key
------+-------+--------+------------+-------------+--------+-------------+----------+-----------
(0 rows)
Expand Down
20 changes: 20 additions & 0 deletions test/sql/0016_materialized_view_in_api.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
begin;
set local search_path = '';
set local pgrst.db_schemas = 'public';

-- 0 issues
select * from lint."0016_materialized_view_in_api";

create materialized view public.my_view as select 1;

-- 1 issue
select * from lint."0016_materialized_view_in_api";

-- Resolve the issue with permissions
revoke select on public.my_view from anon, authenticated, public;

-- 0 issues
select * from lint."0016_materialized_view_in_api";


rollback;
4 changes: 3 additions & 1 deletion test/sql/queries_are_unionable.sql
Original file line number Diff line number Diff line change
Expand Up @@ -28,6 +28,8 @@ begin;
union all
select * from lint."0014_extension_in_public"
union all
select * from lint."0015_rls_references_user_metadata";
select * from lint."0015_rls_references_user_metadata"
union all
select * from lint."0016_materialized_view_in_api";

rollback;
Loading