Skip to content

Commit c62ffd6

Browse files
committed
feat: Adds CRUD for policies
Fixes #31. Note that the update functionality doesn't include action and command. This is because postgres expects a DROP and recreate to alter these settings. I don't want to do that within the PATCH command because it will return a new ID. End users should follow the convention - delete and recreate
1 parent 988fe8b commit c62ffd6

File tree

6 files changed

+283
-21
lines changed

6 files changed

+283
-21
lines changed

src/api.ts

+1
Original file line numberDiff line numberDiff line change
@@ -8,6 +8,7 @@ router.use('/config', addConnectionToRequest, require('./api/config'))
88
router.use('/columns', addConnectionToRequest, require('./api/columns'))
99
router.use('/extensions', addConnectionToRequest, require('./api/extensions'))
1010
router.use('/functions', addConnectionToRequest, require('./api/functions'))
11+
router.use('/policies', addConnectionToRequest, require('./api/policies'))
1112
router.use('/query', addConnectionToRequest, require('./api/query'))
1213
router.use('/schemas', addConnectionToRequest, require('./api/schemas'))
1314
router.use('/tables', addConnectionToRequest, require('./api/tables'))

src/api/policies.ts

+201
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,201 @@
1+
import { Router } from 'express'
2+
import { coalesceRowsToArray, toTransaction } from '../lib/helpers'
3+
import { RunQuery } from '../lib/connectionPool'
4+
import { DEFAULT_SYSTEM_SCHEMAS } from '../lib/constants'
5+
import { Tables } from '../lib/interfaces'
6+
import sqlTemplates = require('../lib/sql')
7+
8+
/**
9+
* @param {string} [includeSystemSchemas=false] - Return system schemas as well as user schemas
10+
*/
11+
interface QueryParams {
12+
includeSystemSchemas?: string
13+
}
14+
15+
const router = Router()
16+
17+
router.get('/', async (req, res) => {
18+
try {
19+
const sql = getAllSql(sqlTemplates)
20+
const { data } = await RunQuery(req.headers.pg, sql)
21+
const query: QueryParams = req.query
22+
const includeSystemSchemas = query?.includeSystemSchemas === 'true'
23+
let payload: Tables.Policy[] = data
24+
if (!includeSystemSchemas) payload = removeSystemSchemas(data)
25+
return res.status(200).json(payload)
26+
} catch (error) {
27+
console.log('throwing error', error)
28+
res.status(500).json({ error: 'Database error', status: 500 })
29+
}
30+
})
31+
32+
router.post('/', async (req, res) => {
33+
try {
34+
const pcConnection: string = req.headers.pg.toString()
35+
const payload: Tables.Policy = { ...req.body }
36+
const schema: string = payload.schema || 'public'
37+
const name: string = payload.name
38+
const table: string = payload.table
39+
40+
// Create
41+
const createSqlString = createSql(payload)
42+
await RunQuery(pcConnection, createSqlString)
43+
44+
// Return fresh details
45+
const newPolicy = await getPolicyByName(pcConnection, name, schema, table)
46+
return res.status(200).json(newPolicy)
47+
} catch (error) {
48+
// For this one, we always want to give back the error to the customer
49+
console.log('POST error!', error)
50+
res.status(200).json([{ error: error.toString() }])
51+
}
52+
})
53+
54+
router.patch('/:id', async (req, res) => {
55+
try {
56+
const pcConnection: string = req.headers.pg.toString()
57+
const id: number = parseInt(req.params.id)
58+
if (!(id > 0)) throw new Error('id is required')
59+
60+
const payload: Tables.Policy = { ...req.body }
61+
const previousPolicy: Tables.Policy = await getPolicyById(pcConnection, id)
62+
const nameChange = !!payload.name && payload.name != previousPolicy.name
63+
let updates = { ...payload }
64+
if (!updates.name) updates.name = previousPolicy.name
65+
if (!updates.schema) updates.schema = previousPolicy.schema
66+
if (!updates.table) updates.table = previousPolicy.table
67+
68+
// Update fields and name
69+
const nameSqlString = nameChange
70+
? alterPolicyNameSql(
71+
previousPolicy.name,
72+
payload.name,
73+
previousPolicy.schema,
74+
previousPolicy.table
75+
)
76+
: ''
77+
const alterSqlString = alterSql(updates)
78+
const transaction = toTransaction([nameSqlString, alterSqlString])
79+
await RunQuery(pcConnection, transaction)
80+
81+
// Return fresh details
82+
const updated = await getPolicyById(pcConnection, id)
83+
return res.status(200).json(updated)
84+
} catch (error) {
85+
// For this one, we always want to give back the error to the customer
86+
console.log('Soft error!', error)
87+
res.status(200).json([{ error: error.toString() }])
88+
}
89+
})
90+
91+
router.delete('/:id', async (req, res) => {
92+
try {
93+
const pcConnection: string = req.headers.pg.toString()
94+
const id: number = parseInt(req.params.id)
95+
if (!(id > 0)) throw new Error('id is required')
96+
97+
// Get
98+
const policy = await getPolicyById(pcConnection, id)
99+
const { name, schema, table } = policy
100+
101+
// Drop
102+
const query = dropSql(name, schema, table)
103+
await RunQuery(pcConnection, query)
104+
105+
return res.status(200).json(policy)
106+
} catch (error) {
107+
console.log('throwing error', error)
108+
res.status(500).json({ error: 'Database error', status: 500 })
109+
}
110+
})
111+
112+
const getAllSql = (sqlTemplates) => {
113+
const { policies } = sqlTemplates
114+
return `${policies}`.trim()
115+
}
116+
const getPolicyById = async (connection: string, id: number) => {
117+
const { policies } = sqlTemplates
118+
let sql = `
119+
with policies as (${policies})
120+
select * from policies
121+
where policies.id = '${id}'
122+
limit 1
123+
`.trim()
124+
const { data } = await RunQuery(connection, sql)
125+
return data[0]
126+
}
127+
const getPolicyByName = async (connection: string, name: string, schema: string, table: string) => {
128+
const { policies } = sqlTemplates
129+
let sql = `
130+
with policies as (${policies})
131+
select * from policies
132+
where policies.name = '${name}' and policies.schema = '${schema}' and policies.table = '${table}'
133+
limit 1
134+
`.trim()
135+
const { data } = await RunQuery(connection, sql)
136+
return data[0]
137+
}
138+
const createSql = ({
139+
name,
140+
table,
141+
definition,
142+
check,
143+
schema = 'postgres',
144+
action = 'PERMISSIVE',
145+
command = 'ALL',
146+
roles = ['PUBLIC'],
147+
}: {
148+
name: string
149+
table: string
150+
definition?: string
151+
check?: string
152+
schema?: string
153+
action?: string
154+
command?: string
155+
roles?: string[]
156+
}) => {
157+
let sql = ` CREATE POLICY "${name}" ON "${schema}"."${table}"
158+
AS ${action}
159+
FOR ${command}
160+
TO ${roles.join(',')} `.trim()
161+
if (definition) sql += ` USING (${definition}) `
162+
if (check) sql += ` WITH CHECK (${check}) `
163+
sql += ';'
164+
return sql
165+
}
166+
const alterPolicyNameSql = (oldName: string, newName: string, schema: string, table: string) => {
167+
return `ALTER POLICY "${oldName}" ON "${schema}"."${table}" RENAME TO "${newName}";`.trim()
168+
}
169+
const alterSql = ({
170+
name,
171+
schema,
172+
table,
173+
definition,
174+
check,
175+
roles,
176+
}: {
177+
schema: string
178+
name: string
179+
table: string
180+
definition?: string
181+
check?: string
182+
roles?: string[]
183+
}) => {
184+
let alter = `ALTER POLICY "${name}" ON "${schema}"."${table}"`
185+
let newDefinition = definition !== undefined ? `${alter} USING (${definition});` : ''
186+
let newCheck = check !== undefined ? `${alter} WITH CHECK (${check});` : ''
187+
let newRoles = roles !== undefined ? `${alter} TO (${roles.join(',')});` : ''
188+
189+
return `
190+
${newDefinition}
191+
${newCheck}
192+
${newRoles}`.trim()
193+
}
194+
const dropSql = (name: string, schema: string, table: string) => {
195+
return `DROP POLICY "${name}" ON "${schema}"."${table}";`.trim()
196+
}
197+
const removeSystemSchemas = (data: Tables.Policy[]) => {
198+
return data.filter((x) => !DEFAULT_SYSTEM_SCHEMAS.includes(x.schema))
199+
}
200+
201+
export = router

src/lib/helpers.ts

+1-1
Original file line numberDiff line numberDiff line change
@@ -17,7 +17,7 @@ COALESCE(
1717
export const toTransaction = (statements: string[]) => {
1818
let cleansed = statements.map((x) => {
1919
let sql = x.trim()
20-
if (x.slice(-1) !== ';') sql += ';'
20+
if (sql.length > 0 && x.slice(-1) !== ';') sql += ';'
2121
return sql
2222
})
2323
let allStatements = cleansed.join('')

src/lib/interfaces.ts

+4-3
Original file line numberDiff line numberDiff line change
@@ -115,14 +115,15 @@ export namespace Tables {
115115

116116
export interface Policy {
117117
id: number
118+
name: string
118119
schema: string
119120
table: string
120121
table_id: number
121-
permissive: boolean
122+
action: 'PERMISSIVE' | 'RESTRICTIVE'
122123
roles: string[]
123-
cmd: string
124+
command: string
124125
definition: string
125-
with_check: string
126+
check: string
126127
}
127128

128129
export interface PrimaryKey {

src/lib/sql/policies.sql

+5-5
Original file line numberDiff line numberDiff line change
@@ -1,13 +1,13 @@
11
select
2-
n.oid as id,
2+
pol.oid as id,
33
n.nspname AS schema,
44
c.relname AS table,
55
c.oid AS table_id,
66
pol.polname AS name,
77
CASE
88
WHEN pol.polpermissive THEN 'PERMISSIVE' :: text
99
ELSE 'RESTRICTIVE' :: text
10-
END AS permissive,
10+
END AS action,
1111
CASE
1212
WHEN pol.polroles = '{0}' :: oid []
1313
THEN array_to_json(string_to_array('public' :: text, '' :: text) :: name [])
@@ -30,9 +30,9 @@ select
3030
WHEN 'd' :: "char" THEN 'DELETE' :: text
3131
WHEN '*' :: "char" THEN 'ALL' :: text
3232
ELSE NULL :: text
33-
END AS cmd,
34-
pg_get_expr(pol.polqual, pol.polrelid) AS qual,
35-
pg_get_expr(pol.polwithcheck, pol.polrelid) AS with_check
33+
END AS command,
34+
pg_get_expr(pol.polqual, pol.polrelid) AS definition,
35+
pg_get_expr(pol.polwithcheck, pol.polrelid) AS check
3636
FROM
3737
pg_policy pol
3838
JOIN pg_class c ON c.oid = pol.polrelid

test/integration/index.spec.js

+71-12
Original file line numberDiff line numberDiff line change
@@ -174,18 +174,18 @@ describe('/tables', async () => {
174174
const nameColumn = datum.columns.find((x) => x.name === 'name')
175175
const statusColumn = memes.columns.find((x) => x.name ==='status')
176176
assert.equal(tables.status, STATUS.SUCCESS)
177-
assert.equal(true, !!datum)
178-
assert.equal(true, !notIncluded)
179-
assert.equal(datum['rls_enabled'], false)
180-
assert.equal(datum['rls_forced'], false)
181-
assert.equal(datum.columns.length > 0, true)
182-
assert.equal(datum.primary_keys.length > 0, true)
183-
assert.equal(idColumn.is_updatable, true)
184-
assert.equal(idColumn.is_identity, true)
185-
assert.equal(nameColumn.is_identity, false)
186-
assert.equal(datum.grants.length > 0, true)
187-
assert.equal(datum.policies.length == 0, true)
188-
assert.equal(statusColumn.enums[0], 'new')
177+
assert.equal(true, !!datum, 'Table included')
178+
assert.equal(true, !notIncluded, 'System table not included')
179+
assert.equal(datum['rls_enabled'], false, 'RLS false')
180+
assert.equal(datum['rls_forced'], false, 'RLS Forced')
181+
assert.equal(datum.columns.length > 0, true, 'Has columns')
182+
assert.equal(datum.primary_keys.length > 0, true, 'Has PK')
183+
assert.equal(idColumn.is_updatable, true, 'Is updatable')
184+
assert.equal(idColumn.is_identity, true, 'ID is Identity')
185+
assert.equal(nameColumn.is_identity, false, 'Name is not identity')
186+
assert.equal(datum.grants.length > 0, true, 'Has grants')
187+
assert.equal(datum.policies.length == 0, true, 'Has no policies')
188+
assert.equal(statusColumn.enums[0], 'new', 'Has enums')
189189
})
190190
it('/tables should return the relationships', async () => {
191191
const tables = await axios.get(`${URL}/tables`)
@@ -443,3 +443,62 @@ describe('/roles', () => {
443443
assert.equal(newRoleExists, false)
444444
})
445445
})
446+
describe('/policies', () => {
447+
var policy = {
448+
id: null,
449+
name: 'test policy',
450+
schema: 'public',
451+
table: 'memes',
452+
action: 'RESTRICTIVE'
453+
}
454+
before(async () => {
455+
await axios.post(`${URL}/query`, {
456+
query: `DROP POLICY IF EXISTS "${policy.name}" on "${policy.schema}"."${policy.table}" `,
457+
})
458+
})
459+
it('GET', async () => {
460+
const res = await axios.get(`${URL}/policies`)
461+
// console.log('res', res)
462+
const policy = res.data[0]
463+
assert.equal('id' in policy, true, 'Has ID')
464+
assert.equal('name' in policy, true, 'Has name')
465+
assert.equal('action' in policy, true, 'Has action')
466+
assert.equal('table' in policy, true, 'Has table')
467+
assert.equal('table_id' in policy, true, 'Has table_id')
468+
assert.equal('roles' in policy, true, 'Has roles')
469+
assert.equal('command' in policy, true, 'Has command')
470+
assert.equal('definition' in policy, true, 'Has definition')
471+
assert.equal('check' in policy, true, 'Has check')
472+
})
473+
it('POST', async () => {
474+
const { data: newPolicy } = await axios.post(`${URL}/policies`, policy)
475+
assert.equal(newPolicy.name, 'test policy')
476+
assert.equal(newPolicy.schema, 'public')
477+
assert.equal(newPolicy.table, 'memes')
478+
assert.equal(newPolicy.action, 'RESTRICTIVE')
479+
assert.equal(newPolicy.roles[0], 'public')
480+
assert.equal(newPolicy.command, 'ALL')
481+
assert.equal(newPolicy.definition, null)
482+
assert.equal(newPolicy.check, null)
483+
policy.id = newPolicy.id
484+
})
485+
it('PATCH', async () => {
486+
const updates = {
487+
name: 'policy updated',
488+
definition: `current_setting('my.username') IN (name)`,
489+
check: `current_setting('my.username') IN (name)`,
490+
}
491+
let { data: updated } = await axios.patch(`${URL}/policies/${policy.id}`, updates)
492+
// console.log('updated', updated)
493+
assert.equal(updated.id, policy.id)
494+
assert.equal(updated.name, 'policy updated', 'name updated')
495+
assert.notEqual(updated.definition, null, 'definition updated')
496+
assert.notEqual(updated.check, null, 'check updated')
497+
})
498+
it('DELETE', async () => {
499+
await axios.delete(`${URL}/policies/${policy.id}`)
500+
const { data: policies } = await axios.get(`${URL}/policies`)
501+
const stillExists = policies.some((x) => policy.id === x.id)
502+
assert.equal(stillExists, false, 'Policy is deleted')
503+
})
504+
})

0 commit comments

Comments
 (0)