Skip to content

Commit 27c9325

Browse files
committed
feat: column privileges
1 parent 7b029b7 commit 27c9325

File tree

9 files changed

+682
-2
lines changed

9 files changed

+682
-2
lines changed

src/lib/PostgresMeta.ts

Lines changed: 4 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,6 @@
11
import { PoolConfig } from 'pg'
22
import * as Parser from './Parser.js'
3+
import PostgresMetaColumnPrivileges from './PostgresMetaColumnPrivileges.js'
34
import PostgresMetaColumns from './PostgresMetaColumns.js'
45
import PostgresMetaConfig from './PostgresMetaConfig.js'
56
import PostgresMetaExtensions from './PostgresMetaExtensions.js'
@@ -23,6 +24,7 @@ import { PostgresMetaResult } from './types.js'
2324
export default class PostgresMeta {
2425
query: (sql: string) => Promise<PostgresMetaResult<any>>
2526
end: () => Promise<void>
27+
columnPrivileges: PostgresMetaColumnPrivileges
2628
columns: PostgresMetaColumns
2729
config: PostgresMetaConfig
2830
extensions: PostgresMetaExtensions
@@ -34,8 +36,8 @@ export default class PostgresMeta {
3436
relationships: PostgresMetaRelationships
3537
roles: PostgresMetaRoles
3638
schemas: PostgresMetaSchemas
37-
tables: PostgresMetaTables
3839
tablePrivileges: PostgresMetaTablePrivileges
40+
tables: PostgresMetaTables
3941
triggers: PostgresMetaTriggers
4042
types: PostgresMetaTypes
4143
version: PostgresMetaVersion
@@ -49,6 +51,7 @@ export default class PostgresMeta {
4951
const { query, end } = init(config)
5052
this.query = query
5153
this.end = end
54+
this.columnPrivileges = new PostgresMetaColumnPrivileges(this.query)
5255
this.columns = new PostgresMetaColumns(this.query)
5356
this.config = new PostgresMetaConfig(this.query)
5457
this.extensions = new PostgresMetaExtensions(this.query)
Lines changed: 141 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,141 @@
1+
import { ident, literal } from 'pg-format'
2+
import { DEFAULT_SYSTEM_SCHEMAS } from './constants.js'
3+
import { filterByList } from './helpers.js'
4+
import { columnPrivilegesSql } from './sql/index.js'
5+
import {
6+
PostgresMetaResult,
7+
PostgresColumnPrivileges,
8+
PostgresColumnPrivilegesGrant,
9+
PostgresColumnPrivilegesRevoke,
10+
} from './types.js'
11+
12+
export default class PostgresMetaColumnPrivileges {
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<PostgresColumnPrivileges[]>> {
32+
let sql = `
33+
with column_privileges as (${columnPrivilegesSql})
34+
select *
35+
from column_privileges
36+
`
37+
const filter = filterByList(
38+
includedSchemas,
39+
excludedSchemas,
40+
!includeSystemSchemas ? DEFAULT_SYSTEM_SCHEMAS : undefined
41+
)
42+
if (filter) {
43+
sql += ` where relation_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 grant(
55+
grants: PostgresColumnPrivilegesGrant[]
56+
): Promise<PostgresMetaResult<PostgresColumnPrivileges[]>> {
57+
let sql = `
58+
do $$
59+
declare
60+
col record;
61+
begin
62+
${grants
63+
.map(({ privilege_type, column_id, grantee, is_grantable }) => {
64+
const [relationId, columnNumber] = column_id.split('.')
65+
return `
66+
select *
67+
from pg_attribute a
68+
where a.attrelid = ${literal(relationId)}
69+
and a.attnum = ${literal(columnNumber)}
70+
into col;
71+
execute format(
72+
'grant ${privilege_type} (%I) on %I to ${
73+
grantee.toLowerCase() === 'public' ? 'public' : ident(grantee)
74+
} ${is_grantable ? 'with grant option' : ''}',
75+
col.attname,
76+
col.attrelid::regclass
77+
);`
78+
})
79+
.join('\n')}
80+
end $$;
81+
`
82+
const { data, error } = await this.query(sql)
83+
if (error) {
84+
return { data, error }
85+
}
86+
87+
// Return the updated column privileges for modified columns.
88+
const columnIds = [...new Set(grants.map(({ column_id }) => column_id))]
89+
sql = `
90+
with column_privileges as (${columnPrivilegesSql})
91+
select *
92+
from column_privileges
93+
where column_id in (${columnIds.map(literal).join(',')})
94+
`
95+
return await this.query(sql)
96+
}
97+
98+
async revoke(
99+
revokes: PostgresColumnPrivilegesRevoke[]
100+
): Promise<PostgresMetaResult<PostgresColumnPrivileges[]>> {
101+
let sql = `
102+
do $$
103+
declare
104+
col record;
105+
begin
106+
${revokes
107+
.map(({ privilege_type, column_id, grantee }) => {
108+
const [relationId, columnNumber] = column_id.split('.')
109+
return `
110+
select *
111+
from pg_attribute a
112+
where a.attrelid = ${literal(relationId)}
113+
and a.attnum = ${literal(columnNumber)}
114+
into col;
115+
execute format(
116+
'revoke ${privilege_type} (%I) on %I from ${
117+
grantee.toLowerCase() === 'public' ? 'public' : ident(grantee)
118+
}',
119+
col.attname,
120+
col.attrelid::regclass
121+
);`
122+
})
123+
.join('\n')}
124+
end $$;
125+
`
126+
const { data, error } = await this.query(sql)
127+
if (error) {
128+
return { data, error }
129+
}
130+
131+
// Return the updated column privileges for modified columns.
132+
const columnIds = [...new Set(revokes.map(({ column_id }) => column_id))]
133+
sql = `
134+
with column_privileges as (${columnPrivilegesSql})
135+
select *
136+
from column_privileges
137+
where column_id in (${columnIds.map(literal).join(',')})
138+
`
139+
return await this.query(sql)
140+
}
141+
}

src/lib/sql/column_privileges.sql

Lines changed: 145 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,145 @@
1+
-- Lists each column's privileges in the form of:
2+
--
3+
-- [
4+
-- {
5+
-- "column_id": "12345.1",
6+
-- "relation_schema": "public",
7+
-- "relation_name": "mytable",
8+
-- "column_name": "mycolumn",
9+
-- "privileges": [
10+
-- {
11+
-- "grantor": "postgres",
12+
-- "grantee": "myrole",
13+
-- "privilege_type": "SELECT",
14+
-- "is_grantable": false
15+
-- },
16+
-- ...
17+
-- ]
18+
-- },
19+
-- ...
20+
-- ]
21+
--
22+
-- Modified from information_schema.column_privileges. We try to be as close as
23+
-- possible to the view definition, obtained from:
24+
--
25+
-- select pg_get_viewdef('information_schema.column_privileges');
26+
--
27+
-- The main differences are:
28+
-- - we include column privileges for materialized views
29+
-- (reason for exclusion in information_schema.column_privileges:
30+
-- https://www.postgresql.org/message-id/9136.1502740844%40sss.pgh.pa.us)
31+
-- - we query a.attrelid and a.attnum to generate `column_id`
32+
-- - `table_catalog` is omitted
33+
-- - table_schema -> relation_schema, table_name -> relation_name
34+
--
35+
-- Column privileges are intertwined with table privileges in that table
36+
-- privileges override column privileges. E.g. if we do:
37+
--
38+
-- grant all on mytable to myrole;
39+
--
40+
-- Then `myrole` is granted privileges for ALL columns. Likewise, if we do:
41+
--
42+
-- grant all (id) on mytable to myrole;
43+
-- revoke all on mytable from myrole;
44+
--
45+
-- Then the grant on the `id` column is revoked.
46+
--
47+
-- This is unlike how grants for schemas and tables interact, where you need
48+
-- privileges for BOTH the schema the table is in AND the table itself in order
49+
-- to access the table.
50+
51+
select (x.attrelid || '.' || x.attnum) as column_id,
52+
nc.nspname as relation_schema,
53+
x.relname as relation_name,
54+
x.attname as column_name,
55+
coalesce(
56+
jsonb_agg(
57+
jsonb_build_object(
58+
'grantor', u_grantor.rolname,
59+
'grantee', grantee.rolname,
60+
'privilege_type', x.prtype,
61+
'is_grantable', x.grantable
62+
)
63+
),
64+
'[]'
65+
) as privileges
66+
from
67+
(select pr_c.grantor,
68+
pr_c.grantee,
69+
a.attrelid,
70+
a.attnum,
71+
a.attname,
72+
pr_c.relname,
73+
pr_c.relnamespace,
74+
pr_c.prtype,
75+
pr_c.grantable,
76+
pr_c.relowner
77+
from
78+
(select pg_class.oid,
79+
pg_class.relname,
80+
pg_class.relnamespace,
81+
pg_class.relowner,
82+
(aclexplode(coalesce(pg_class.relacl, acldefault('r', pg_class.relowner)))).grantor as grantor,
83+
(aclexplode(coalesce(pg_class.relacl, acldefault('r', pg_class.relowner)))).grantee as grantee,
84+
(aclexplode(coalesce(pg_class.relacl, acldefault('r', pg_class.relowner)))).privilege_type as privilege_type,
85+
(aclexplode(coalesce(pg_class.relacl, acldefault('r', pg_class.relowner)))).is_grantable as is_grantable
86+
from pg_class
87+
where (pg_class.relkind = any (array['r',
88+
'v',
89+
'm',
90+
'f',
91+
'p'])) ) pr_c(oid, relname, relnamespace, relowner, grantor, grantee, prtype, grantable),
92+
pg_attribute a
93+
where ((a.attrelid = pr_c.oid)
94+
and (a.attnum > 0)
95+
and (not a.attisdropped))
96+
union select pr_a.grantor,
97+
pr_a.grantee,
98+
pr_a.attrelid,
99+
pr_a.attnum,
100+
pr_a.attname,
101+
c.relname,
102+
c.relnamespace,
103+
pr_a.prtype,
104+
pr_a.grantable,
105+
c.relowner
106+
from
107+
(select a.attrelid,
108+
a.attnum,
109+
a.attname,
110+
(aclexplode(coalesce(a.attacl, acldefault('c', cc.relowner)))).grantor as grantor,
111+
(aclexplode(coalesce(a.attacl, acldefault('c', cc.relowner)))).grantee as grantee,
112+
(aclexplode(coalesce(a.attacl, acldefault('c', cc.relowner)))).privilege_type as privilege_type,
113+
(aclexplode(coalesce(a.attacl, acldefault('c', cc.relowner)))).is_grantable as is_grantable
114+
from (pg_attribute a
115+
join pg_class cc on ((a.attrelid = cc.oid)))
116+
where ((a.attnum > 0)
117+
and (not a.attisdropped))) pr_a(attrelid, attnum, attname, grantor, grantee, prtype, grantable),
118+
pg_class c
119+
where ((pr_a.attrelid = c.oid)
120+
and (c.relkind = any (ARRAY['r',
121+
'v',
122+
'm',
123+
'f',
124+
'p'])))) x,
125+
pg_namespace nc,
126+
pg_authid u_grantor,
127+
(select pg_authid.oid,
128+
pg_authid.rolname
129+
from pg_authid
130+
union all select (0)::oid as oid,
131+
'PUBLIC') grantee(oid, rolname)
132+
where ((x.relnamespace = nc.oid)
133+
and (x.grantee = grantee.oid)
134+
and (x.grantor = u_grantor.oid)
135+
and (x.prtype = any (ARRAY['INSERT',
136+
'SELECT',
137+
'UPDATE',
138+
'REFERENCES']))
139+
and (pg_has_role(u_grantor.oid, 'USAGE')
140+
or pg_has_role(grantee.oid, 'USAGE')
141+
or (grantee.rolname = 'PUBLIC')))
142+
group by column_id,
143+
nc.nspname,
144+
x.relname,
145+
x.attname

src/lib/sql/index.ts

Lines changed: 2 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -3,6 +3,7 @@ import { dirname, join } from 'path'
33
import { fileURLToPath } from 'url'
44

55
const __dirname = dirname(fileURLToPath(import.meta.url))
6+
export const columnPrivilegesSql = await readFile(join(__dirname, 'column_privileges.sql'), 'utf-8')
67
export const columnsSql = await readFile(join(__dirname, 'columns.sql'), 'utf-8')
78
export const configSql = await readFile(join(__dirname, 'config.sql'), 'utf-8')
89
export const extensionsSql = await readFile(join(__dirname, 'extensions.sql'), 'utf-8')
@@ -20,8 +21,8 @@ export const tableRelationshipsSql = await readFile(
2021
)
2122
export const rolesSql = await readFile(join(__dirname, 'roles.sql'), 'utf-8')
2223
export const schemasSql = await readFile(join(__dirname, 'schemas.sql'), 'utf-8')
23-
export const tablesSql = await readFile(join(__dirname, 'tables.sql'), 'utf-8')
2424
export const tablePrivilegesSql = await readFile(join(__dirname, 'table_privileges.sql'), 'utf-8')
25+
export const tablesSql = await readFile(join(__dirname, 'tables.sql'), 'utf-8')
2526
export const triggersSql = await readFile(join(__dirname, 'triggers.sql'), 'utf-8')
2627
export const typesSql = await readFile(join(__dirname, 'types.sql'), 'utf-8')
2728
export const versionSql = await readFile(join(__dirname, 'version.sql'), 'utf-8')

src/lib/types.ts

Lines changed: 48 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -467,3 +467,51 @@ export const postgresTablePrivilegesRevokeSchema = Type.Object({
467467
]),
468468
})
469469
export type PostgresTablePrivilegesRevoke = Static<typeof postgresTablePrivilegesRevokeSchema>
470+
471+
export const postgresColumnPrivilegesSchema = Type.Object({
472+
column_id: Type.RegEx(/^(\d+)\.(\d+)$/),
473+
relation_schema: Type.String(),
474+
relation_name: Type.String(),
475+
column_name: Type.String(),
476+
privileges: Type.Array(
477+
Type.Object({
478+
grantor: Type.String(),
479+
grantee: Type.String(),
480+
privilege_type: Type.Union([
481+
Type.Literal('SELECT'),
482+
Type.Literal('INSERT'),
483+
Type.Literal('UPDATE'),
484+
Type.Literal('REFERENCES'),
485+
]),
486+
is_grantable: Type.Boolean(),
487+
})
488+
),
489+
})
490+
export type PostgresColumnPrivileges = Static<typeof postgresColumnPrivilegesSchema>
491+
492+
export const postgresColumnPrivilegesGrantSchema = Type.Object({
493+
column_id: Type.RegEx(/^(\d+)\.(\d+)$/),
494+
grantee: Type.String(),
495+
privilege_type: Type.Union([
496+
Type.Literal('ALL'),
497+
Type.Literal('SELECT'),
498+
Type.Literal('INSERT'),
499+
Type.Literal('UPDATE'),
500+
Type.Literal('REFERENCES'),
501+
]),
502+
is_grantable: Type.Optional(Type.Boolean()),
503+
})
504+
export type PostgresColumnPrivilegesGrant = Static<typeof postgresColumnPrivilegesGrantSchema>
505+
506+
export const postgresColumnPrivilegesRevokeSchema = Type.Object({
507+
column_id: Type.RegEx(/^(\d+)\.(\d+)$/),
508+
grantee: Type.String(),
509+
privilege_type: Type.Union([
510+
Type.Literal('ALL'),
511+
Type.Literal('SELECT'),
512+
Type.Literal('INSERT'),
513+
Type.Literal('UPDATE'),
514+
Type.Literal('REFERENCES'),
515+
]),
516+
})
517+
export type PostgresColumnPrivilegesRevoke = Static<typeof postgresColumnPrivilegesRevokeSchema>

0 commit comments

Comments
 (0)