Skip to content

Commit 61ff753

Browse files
committed
test: role privileges on vault objects and indexes
Improves the previous tests while reducing britleness and revealing more implicit privileges. - Reveals privileges on the `_crypto_aead_det_*` functions. - Avoids testing the signature of functions, which is already done on z_15_ext_interface.out. (https://github.com/supabase/postgres/blob/9bdefbcb7cc00b0692562c889b6c7d625120bd66/nix/tests/expected/z_15_ext_interface.out#L4754-L4755) - Unique index test is maintained while also revealing the index owner. - Avoids testing error messages, which can change across versions. - Avoids testing implementation details, and reduces verboseness.
1 parent 67fb756 commit 61ff753

File tree

2 files changed

+138
-69
lines changed

2 files changed

+138
-69
lines changed

nix/tests/expected/vault.out

+86-40
Original file line numberDiff line numberDiff line change
@@ -1,42 +1,88 @@
1-
select
2-
1
3-
from
4-
vault.create_secret('my_s3kre3t');
5-
?column?
6-
----------
7-
1
8-
(1 row)
1+
-- Tests role privileges on the vault objects
2+
-- INSERT and UPDATE privileges should not be present on the vault tables for postgres and service_role, only SELECT and DELETE
3+
WITH schema_obj AS (
4+
SELECT oid, nspname
5+
FROM pg_namespace
6+
WHERE nspname = 'vault'
7+
)
8+
SELECT
9+
s.nspname AS schema,
10+
c.relname AS object_name,
11+
acl.grantee::regrole::text AS grantee,
12+
acl.privilege_type
13+
FROM pg_class c
14+
JOIN schema_obj s ON s.oid = c.relnamespace
15+
CROSS JOIN LATERAL aclexplode(c.relacl) AS acl
16+
WHERE c.relkind IN ('r', 'v', 'm', 'f', 'p')
17+
AND acl.privilege_type <> 'MAINTAIN'
18+
UNION ALL
19+
SELECT
20+
s.nspname AS schema,
21+
p.proname AS object_name,
22+
acl.grantee::regrole::text AS grantee,
23+
acl.privilege_type
24+
FROM pg_proc p
25+
JOIN schema_obj s ON s.oid = p.pronamespace
26+
CROSS JOIN LATERAL aclexplode(p.proacl) AS acl
27+
ORDER BY object_name, grantee, privilege_type;
28+
schema | object_name | grantee | privilege_type
29+
--------+---------------------------+----------------+----------------
30+
vault | _crypto_aead_det_decrypt | postgres | EXECUTE
31+
vault | _crypto_aead_det_decrypt | supabase_admin | EXECUTE
32+
vault | _crypto_aead_det_encrypt | supabase_admin | EXECUTE
33+
vault | _crypto_aead_det_noncegen | supabase_admin | EXECUTE
34+
vault | create_secret | postgres | EXECUTE
35+
vault | create_secret | supabase_admin | EXECUTE
36+
vault | decrypted_secrets | postgres | DELETE
37+
vault | decrypted_secrets | postgres | SELECT
38+
vault | decrypted_secrets | supabase_admin | DELETE
39+
vault | decrypted_secrets | supabase_admin | INSERT
40+
vault | decrypted_secrets | supabase_admin | REFERENCES
41+
vault | decrypted_secrets | supabase_admin | SELECT
42+
vault | decrypted_secrets | supabase_admin | TRIGGER
43+
vault | decrypted_secrets | supabase_admin | TRUNCATE
44+
vault | decrypted_secrets | supabase_admin | UPDATE
45+
vault | secrets | postgres | DELETE
46+
vault | secrets | postgres | SELECT
47+
vault | secrets | supabase_admin | DELETE
48+
vault | secrets | supabase_admin | INSERT
49+
vault | secrets | supabase_admin | REFERENCES
50+
vault | secrets | supabase_admin | SELECT
51+
vault | secrets | supabase_admin | TRIGGER
52+
vault | secrets | supabase_admin | TRUNCATE
53+
vault | secrets | supabase_admin | UPDATE
54+
vault | update_secret | postgres | EXECUTE
55+
vault | update_secret | supabase_admin | EXECUTE
56+
(26 rows)
957

10-
select
11-
1
12-
from
13-
vault.create_secret(
14-
'another_s3kre3t',
15-
'unique_name',
16-
'This is the description'
17-
);
18-
?column?
19-
----------
20-
1
21-
(1 row)
58+
-- vault indexes with owners
59+
SELECT
60+
ns.nspname AS schema,
61+
t.relname AS table,
62+
i.relname AS index_name,
63+
r.rolname AS index_owner,
64+
CASE
65+
WHEN idx.indisunique THEN 'Unique'
66+
ELSE 'Non Unique'
67+
END AS index_type
68+
FROM
69+
pg_class t
70+
JOIN
71+
pg_namespace ns ON t.relnamespace = ns.oid
72+
JOIN
73+
pg_index idx ON t.oid = idx.indrelid
74+
JOIN
75+
pg_class i ON idx.indexrelid = i.oid
76+
JOIN
77+
pg_roles r ON i.relowner = r.oid
78+
WHERE
79+
ns.nspname = 'vault'
80+
ORDER BY
81+
t.relname,
82+
i.relname;
83+
schema | table | index_name | index_owner | index_type
84+
--------+---------+------------------+----------------+------------
85+
vault | secrets | secrets_name_idx | supabase_admin | Unique
86+
vault | secrets | secrets_pkey | supabase_admin | Unique
87+
(2 rows)
2288

23-
insert into vault.secrets (secret)
24-
values
25-
('s3kre3t_k3y');
26-
select
27-
name,
28-
description
29-
from
30-
vault.decrypted_secrets
31-
order by
32-
created_at desc
33-
limit
34-
3;
35-
name | description
36-
-------------+-------------------------
37-
|
38-
unique_name | This is the description
39-
|
40-
(3 rows)
41-
42-

nix/tests/sql/vault.sql

+52-29
Original file line numberDiff line numberDiff line change
@@ -1,30 +1,53 @@
1-
select
2-
1
3-
from
4-
vault.create_secret('my_s3kre3t');
5-
6-
select
7-
1
8-
from
9-
vault.create_secret(
10-
'another_s3kre3t',
11-
'unique_name',
12-
'This is the description'
13-
);
14-
15-
insert into vault.secrets (secret)
16-
values
17-
('s3kre3t_k3y');
18-
19-
select
20-
name,
21-
description
22-
from
23-
vault.decrypted_secrets
24-
order by
25-
created_at desc
26-
limit
27-
3;
28-
29-
1+
-- Tests role privileges on the vault objects
2+
-- INSERT and UPDATE privileges should not be present on the vault tables for postgres and service_role, only SELECT and DELETE
3+
WITH schema_obj AS (
4+
SELECT oid, nspname
5+
FROM pg_namespace
6+
WHERE nspname = 'vault'
7+
)
8+
SELECT
9+
s.nspname AS schema,
10+
c.relname AS object_name,
11+
acl.grantee::regrole::text AS grantee,
12+
acl.privilege_type
13+
FROM pg_class c
14+
JOIN schema_obj s ON s.oid = c.relnamespace
15+
CROSS JOIN LATERAL aclexplode(c.relacl) AS acl
16+
WHERE c.relkind IN ('r', 'v', 'm', 'f', 'p')
17+
AND acl.privilege_type <> 'MAINTAIN'
18+
UNION ALL
19+
SELECT
20+
s.nspname AS schema,
21+
p.proname AS object_name,
22+
acl.grantee::regrole::text AS grantee,
23+
acl.privilege_type
24+
FROM pg_proc p
25+
JOIN schema_obj s ON s.oid = p.pronamespace
26+
CROSS JOIN LATERAL aclexplode(p.proacl) AS acl
27+
ORDER BY object_name, grantee, privilege_type;
3028

29+
-- vault indexes with owners
30+
SELECT
31+
ns.nspname AS schema,
32+
t.relname AS table,
33+
i.relname AS index_name,
34+
r.rolname AS index_owner,
35+
CASE
36+
WHEN idx.indisunique THEN 'Unique'
37+
ELSE 'Non Unique'
38+
END AS index_type
39+
FROM
40+
pg_class t
41+
JOIN
42+
pg_namespace ns ON t.relnamespace = ns.oid
43+
JOIN
44+
pg_index idx ON t.oid = idx.indrelid
45+
JOIN
46+
pg_class i ON idx.indexrelid = i.oid
47+
JOIN
48+
pg_roles r ON i.relowner = r.oid
49+
WHERE
50+
ns.nspname = 'vault'
51+
ORDER BY
52+
t.relname,
53+
i.relname;

0 commit comments

Comments
 (0)