Skip to content

Commit 72bd1b8

Browse files
committed
feat: table privileges
1 parent 19308c2 commit 72bd1b8

File tree

9 files changed

+613
-0
lines changed

9 files changed

+613
-0
lines changed

src/lib/PostgresMeta.ts

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -11,6 +11,7 @@ import PostgresMetaPublications from './PostgresMetaPublications.js'
1111
import PostgresMetaRelationships from './PostgresMetaRelationships.js'
1212
import PostgresMetaRoles from './PostgresMetaRoles.js'
1313
import PostgresMetaSchemas from './PostgresMetaSchemas.js'
14+
import PostgresMetaTablePrivileges from './PostgresMetaTablePrivileges.js'
1415
import PostgresMetaTables from './PostgresMetaTables.js'
1516
import PostgresMetaTriggers from './PostgresMetaTriggers.js'
1617
import PostgresMetaTypes from './PostgresMetaTypes.js'
@@ -34,6 +35,7 @@ export default class PostgresMeta {
3435
roles: PostgresMetaRoles
3536
schemas: PostgresMetaSchemas
3637
tables: PostgresMetaTables
38+
tablePrivileges: PostgresMetaTablePrivileges
3739
triggers: PostgresMetaTriggers
3840
types: PostgresMetaTypes
3941
version: PostgresMetaVersion
@@ -58,6 +60,7 @@ export default class PostgresMeta {
5860
this.relationships = new PostgresMetaRelationships(this.query)
5961
this.roles = new PostgresMetaRoles(this.query)
6062
this.schemas = new PostgresMetaSchemas(this.query)
63+
this.tablePrivileges = new PostgresMetaTablePrivileges(this.query)
6164
this.tables = new PostgresMetaTables(this.query)
6265
this.triggers = new PostgresMetaTriggers(this.query)
6366
this.types = new PostgresMetaTypes(this.query)
Lines changed: 170 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,170 @@
1+
import { ident, literal } from 'pg-format'
2+
import { DEFAULT_SYSTEM_SCHEMAS } from './constants.js'
3+
import { filterByList } from './helpers.js'
4+
import { tablePrivilegesSql } from './sql/index.js'
5+
import {
6+
PostgresMetaResult,
7+
PostgresTablePrivileges,
8+
PostgresTablePrivilegesGrant,
9+
PostgresTablePrivilegesRevoke,
10+
} from './types.js'
11+
12+
export default class PostgresMetaTablePrivileges {
13+
query: (sql: string) => Promise<PostgresMetaResult<any>>
14+
15+
constructor(query: (sql: string) => Promise<PostgresMetaResult<any>>) {
16+
this.query = query
17+
}
18+
19+
async list({
20+
includeSystemSchemas = false,
21+
includedSchemas,
22+
excludedSchemas,
23+
limit,
24+
offset,
25+
}: {
26+
includeSystemSchemas?: boolean
27+
includedSchemas?: string[]
28+
excludedSchemas?: string[]
29+
limit?: number
30+
offset?: number
31+
} = {}): Promise<PostgresMetaResult<PostgresTablePrivileges[]>> {
32+
let sql = `
33+
with table_privileges as (${tablePrivilegesSql})
34+
select *
35+
from table_privileges
36+
`
37+
const filter = filterByList(
38+
includedSchemas,
39+
excludedSchemas,
40+
!includeSystemSchemas ? DEFAULT_SYSTEM_SCHEMAS : undefined
41+
)
42+
if (filter) {
43+
sql += ` where schema ${filter}`
44+
}
45+
if (limit) {
46+
sql += ` limit ${limit}`
47+
}
48+
if (offset) {
49+
sql += ` offset ${offset}`
50+
}
51+
return await this.query(sql)
52+
}
53+
54+
async retrieve({ id }: { id: number }): Promise<PostgresMetaResult<PostgresTablePrivileges>>
55+
async retrieve({
56+
name,
57+
schema,
58+
}: {
59+
name: string
60+
schema: string
61+
}): Promise<PostgresMetaResult<PostgresTablePrivileges>>
62+
async retrieve({
63+
id,
64+
name,
65+
schema = 'public',
66+
}: {
67+
id?: number
68+
name?: string
69+
schema?: string
70+
}): Promise<PostgresMetaResult<PostgresTablePrivileges>> {
71+
if (id) {
72+
const sql = `
73+
with table_privileges as (${tablePrivilegesSql})
74+
select *
75+
from table_privileges
76+
where table_privileges.relation_id = ${literal(id)};`
77+
const { data, error } = await this.query(sql)
78+
if (error) {
79+
return { data, error }
80+
} else if (data.length === 0) {
81+
return { data: null, error: { message: `Cannot find a relation with ID ${id}` } }
82+
} else {
83+
return { data: data[0], error }
84+
}
85+
} else if (name) {
86+
const sql = `
87+
with table_privileges as (${tablePrivilegesSql})
88+
select *
89+
from table_privileges
90+
where table_privileges.schema = ${literal(schema)}
91+
and table_privileges.name = ${literal(name)}
92+
`
93+
const { data, error } = await this.query(sql)
94+
if (error) {
95+
return { data, error }
96+
} else if (data.length === 0) {
97+
return {
98+
data: null,
99+
error: { message: `Cannot find a relation named ${name} in schema ${schema}` },
100+
}
101+
} else {
102+
return { data: data[0], error }
103+
}
104+
} else {
105+
return { data: null, error: { message: 'Invalid parameters on retrieving table privileges' } }
106+
}
107+
}
108+
109+
async grant(
110+
grants: PostgresTablePrivilegesGrant[]
111+
): Promise<PostgresMetaResult<PostgresTablePrivileges[]>> {
112+
let sql = `
113+
do $$
114+
begin
115+
${grants
116+
.map(
117+
({ privilege_type, relation_id, grantee, is_grantable }) =>
118+
`execute format('grant ${privilege_type} on table %I to ${
119+
grantee.toLowerCase() === 'public' ? 'public' : ident(grantee)
120+
} ${is_grantable ? 'with grant option' : ''}', ${relation_id}::regclass);`
121+
)
122+
.join('\n')}
123+
end $$;
124+
`
125+
const { data, error } = await this.query(sql)
126+
if (error) {
127+
return { data, error }
128+
}
129+
130+
// Return the updated table privileges for modified relations.
131+
const relationIds = [...new Set(grants.map(({ relation_id }) => relation_id))]
132+
sql = `
133+
with table_privileges as (${tablePrivilegesSql})
134+
select *
135+
from table_privileges
136+
where relation_id in (${relationIds.map(literal).join(',')})
137+
`
138+
return await this.query(sql)
139+
}
140+
141+
async revoke(
142+
revokes: PostgresTablePrivilegesRevoke[]
143+
): Promise<PostgresMetaResult<PostgresTablePrivileges[]>> {
144+
let sql = `
145+
do $$
146+
begin
147+
${revokes
148+
.map(
149+
(revoke) =>
150+
`execute format('revoke ${revoke.privilege_type} on table %I from ${revoke.grantee}', ${revoke.relation_id}::regclass);`
151+
)
152+
.join('\n')}
153+
end $$;
154+
`
155+
const { data, error } = await this.query(sql)
156+
if (error) {
157+
return { data, error }
158+
}
159+
160+
// Return the updated table privileges for modified relations.
161+
const relationIds = [...new Set(revokes.map(({ relation_id }) => relation_id))]
162+
sql = `
163+
with table_privileges as (${tablePrivilegesSql})
164+
select *
165+
from table_privileges
166+
where relation_id in (${relationIds.map(literal).join(',')})
167+
`
168+
return await this.query(sql)
169+
}
170+
}

src/lib/sql/index.ts

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -21,6 +21,7 @@ export const tableRelationshipsSql = await readFile(
2121
export const rolesSql = await readFile(join(__dirname, 'roles.sql'), 'utf-8')
2222
export const schemasSql = await readFile(join(__dirname, 'schemas.sql'), 'utf-8')
2323
export const tablesSql = await readFile(join(__dirname, 'tables.sql'), 'utf-8')
24+
export const tablePrivilegesSql = await readFile(join(__dirname, 'table_privileges.sql'), 'utf-8')
2425
export const triggersSql = await readFile(join(__dirname, 'triggers.sql'), 'utf-8')
2526
export const typesSql = await readFile(join(__dirname, 'types.sql'), 'utf-8')
2627
export const versionSql = await readFile(join(__dirname, 'version.sql'), 'utf-8')

src/lib/sql/table_privileges.sql

Lines changed: 75 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,75 @@
1+
-- Despite the name `table_privileges`, this includes other kinds of relations:
2+
-- views, matviews, etc. "Relation privileges" just doesn't roll off the tongue.
3+
--
4+
-- For each relation, get its relacl in a jsonb format,
5+
-- e.g.
6+
--
7+
-- '{postgres=arwdDxt/postgres}'
8+
--
9+
-- becomes
10+
--
11+
-- [
12+
-- {
13+
-- "grantee": "postgres",
14+
-- "grantor": "postgres",
15+
-- "is_grantable": false,
16+
-- "privilege_type": "INSERT"
17+
-- },
18+
-- ...
19+
-- ]
20+
select
21+
c.oid as relation_id,
22+
nc.nspname as schema,
23+
c.relname as name,
24+
case
25+
when c.relkind = 'r' then 'table'
26+
when c.relkind = 'v' then 'view'
27+
when c.relkind = 'm' then 'materialized view'
28+
when c.relkind = 'f' then 'foreign table'
29+
when c.relkind = 'p' then 'partitioned table'
30+
end as kind,
31+
coalesce(
32+
jsonb_agg(
33+
jsonb_build_object(
34+
'grantor', grantor.rolname,
35+
'grantee', grantee.rolname,
36+
'privilege_type', _priv.privilege_type,
37+
'is_grantable', _priv.is_grantable
38+
)
39+
) filter (where _priv is not null),
40+
'[]'
41+
) as privileges
42+
from pg_class c
43+
join pg_namespace as nc
44+
on nc.oid = c.relnamespace
45+
left join lateral (
46+
select grantor, grantee, privilege_type, is_grantable
47+
from aclexplode(coalesce(c.relacl, acldefault('r', c.relowner)))
48+
) as _priv on true
49+
left join pg_roles as grantor
50+
on grantor.oid = _priv.grantor
51+
left join (
52+
select
53+
pg_roles.oid,
54+
pg_roles.rolname
55+
from pg_roles
56+
union all
57+
select
58+
(0)::oid as oid, 'PUBLIC'
59+
) as grantee (oid, rolname)
60+
on grantee.oid = _priv.grantee
61+
where c.relkind in ('r', 'v', 'm', 'f', 'p')
62+
and not pg_is_other_temp_schema(c.relnamespace)
63+
and (
64+
pg_has_role(c.relowner, 'USAGE')
65+
or has_table_privilege(
66+
c.oid,
67+
'SELECT, INSERT, UPDATE, DELETE, TRUNCATE, REFERENCES, TRIGGER'
68+
)
69+
or has_any_column_privilege(c.oid, 'SELECT, INSERT, UPDATE, REFERENCES')
70+
)
71+
group by
72+
c.oid,
73+
nc.nspname,
74+
c.relname,
75+
c.relkind

src/lib/types.ts

Lines changed: 63 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -404,3 +404,66 @@ export const postgresMaterializedViewSchema = Type.Object({
404404
columns: Type.Optional(Type.Array(postgresColumnSchema)),
405405
})
406406
export type PostgresMaterializedView = Static<typeof postgresMaterializedViewSchema>
407+
408+
export const postgresTablePrivilegesSchema = Type.Object({
409+
relation_id: Type.Integer(),
410+
schema: Type.String(),
411+
name: Type.String(),
412+
kind: Type.Union([
413+
Type.Literal('table'),
414+
Type.Literal('view'),
415+
Type.Literal('materialized view'),
416+
Type.Literal('foreign table'),
417+
Type.Literal('partitioned table'),
418+
]),
419+
privileges: Type.Array(
420+
Type.Object({
421+
grantor: Type.String(),
422+
grantee: Type.String(),
423+
privilege_type: Type.Union([
424+
Type.Literal('SELECT'),
425+
Type.Literal('INSERT'),
426+
Type.Literal('UPDATE'),
427+
Type.Literal('DELETE'),
428+
Type.Literal('TRUNCATE'),
429+
Type.Literal('REFERENCES'),
430+
Type.Literal('TRIGGER'),
431+
]),
432+
is_grantable: Type.Boolean(),
433+
})
434+
),
435+
})
436+
export type PostgresTablePrivileges = Static<typeof postgresTablePrivilegesSchema>
437+
438+
export const postgresTablePrivilegesGrantSchema = Type.Object({
439+
relation_id: Type.Integer(),
440+
grantee: Type.String(),
441+
privilege_type: Type.Union([
442+
Type.Literal('ALL'),
443+
Type.Literal('SELECT'),
444+
Type.Literal('INSERT'),
445+
Type.Literal('UPDATE'),
446+
Type.Literal('DELETE'),
447+
Type.Literal('TRUNCATE'),
448+
Type.Literal('REFERENCES'),
449+
Type.Literal('TRIGGER'),
450+
]),
451+
is_grantable: Type.Optional(Type.Boolean()),
452+
})
453+
export type PostgresTablePrivilegesGrant = Static<typeof postgresTablePrivilegesGrantSchema>
454+
455+
export const postgresTablePrivilegesRevokeSchema = Type.Object({
456+
relation_id: Type.Integer(),
457+
grantee: Type.String(),
458+
privilege_type: Type.Union([
459+
Type.Literal('ALL'),
460+
Type.Literal('SELECT'),
461+
Type.Literal('INSERT'),
462+
Type.Literal('UPDATE'),
463+
Type.Literal('DELETE'),
464+
Type.Literal('TRUNCATE'),
465+
Type.Literal('REFERENCES'),
466+
Type.Literal('TRIGGER'),
467+
]),
468+
})
469+
export type PostgresTablePrivilegesRevoke = Static<typeof postgresTablePrivilegesRevokeSchema>

src/server/routes/index.ts

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -11,6 +11,7 @@ import PublicationsRoute from './publications.js'
1111
import QueryRoute from './query.js'
1212
import SchemasRoute from './schemas.js'
1313
import RolesRoute from './roles.js'
14+
import TablePrivilegesRoute from './table-privileges.js'
1415
import TablesRoute from './tables.js'
1516
import TriggersRoute from './triggers.js'
1617
import TypesRoute from './types.js'
@@ -52,6 +53,7 @@ export default async (fastify: FastifyInstance) => {
5253
fastify.register(QueryRoute, { prefix: '/query' })
5354
fastify.register(SchemasRoute, { prefix: '/schemas' })
5455
fastify.register(RolesRoute, { prefix: '/roles' })
56+
fastify.register(TablePrivilegesRoute, { prefix: '/table-privileges' })
5557
fastify.register(TablesRoute, { prefix: '/tables' })
5658
fastify.register(TriggersRoute, { prefix: '/triggers' })
5759
fastify.register(TypesRoute, { prefix: '/types' })

0 commit comments

Comments
 (0)