forked from supabase/splinter
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathsplinter.sql
969 lines (967 loc) · 36.5 KB
/
splinter.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
set local search_path = '';
(
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', '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.<function>()\` 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.<function>() for each row. This produces suboptimal query performance at scale. Resolve the issue by replacing \`auth.<function>()\` with \`(select auth.<function>())\`. 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', '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', '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', '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', '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', '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', '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', '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', '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', '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', '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', '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', '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', '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'), ','))))))