Skip to content

Commit a61465c

Browse files
committed
feat(functions): add args property
Right now we have `argument_types`, but it's not very useful with its current format of a string. The new `args` property has the format ```ts { mode: 'in' | 'out' | 'inout' | 'variadic' | 'table' name: string type_id: number }[] ``` which is easier to consume.
1 parent 84bed8c commit a61465c

File tree

3 files changed

+170
-48
lines changed

3 files changed

+170
-48
lines changed

src/lib/sql/functions.sql

Lines changed: 95 additions & 46 deletions
Original file line numberDiff line numberDiff line change
@@ -1,46 +1,95 @@
1-
SELECT
2-
p.oid :: int8 AS id,
3-
n.nspname AS schema,
4-
p.proname AS name,
5-
l.lanname AS language,
6-
CASE
7-
WHEN l.lanname = 'internal' THEN ''
8-
ELSE p.prosrc
9-
END AS definition,
10-
CASE
11-
WHEN l.lanname = 'internal' THEN p.prosrc
12-
ELSE pg_get_functiondef(p.oid)
13-
END AS complete_statement,
14-
pg_get_function_arguments(p.oid) AS argument_types,
15-
pg_get_function_identity_arguments(p.oid) AS identity_argument_types,
16-
t.typname AS return_type,
17-
CASE
18-
WHEN p.provolatile = 'i' THEN 'IMMUTABLE'
19-
WHEN p.provolatile = 's' THEN 'STABLE'
20-
WHEN p.provolatile = 'v' THEN 'VOLATILE'
21-
END AS behavior,
22-
p.prosecdef AS security_definer,
23-
JSON_OBJECT_AGG(p_config.param, p_config.value)
24-
FILTER (WHERE p_config.param IS NOT NULL) AS config_params
25-
FROM
26-
pg_proc p
27-
LEFT JOIN pg_namespace n ON p.pronamespace = n.oid
28-
LEFT JOIN pg_language l ON p.prolang = l.oid
29-
LEFT JOIN pg_type t ON t.oid = p.prorettype
30-
LEFT JOIN (
31-
SELECT
32-
oid as id,
33-
(string_to_array(unnest(proconfig), '='))[1] AS param,
34-
(string_to_array(unnest(proconfig), '='))[2] AS value
35-
FROM
36-
pg_proc
37-
) p_config ON p_config.id = p.oid
38-
GROUP BY
39-
p.oid,
40-
n.nspname,
41-
p.proname,
42-
l.lanname,
43-
p.prosrc,
44-
t.typname,
45-
p.provolatile,
46-
p.prosecdef
1+
-- CTE with sane arg_modes, arg_names, and arg_types.
2+
-- All three are always of the same length.
3+
-- All three include all args, including OUT and TABLE args.
4+
with functions as (
5+
select
6+
*,
7+
-- proargmodes is null when all arg modes are IN
8+
coalesce(
9+
p.proargmodes,
10+
array_fill('i'::text, array[cardinality(coalesce(p.proallargtypes, p.proargtypes))])
11+
) as arg_modes,
12+
-- proargnames is null when all args are unnamed
13+
coalesce(
14+
p.proargnames,
15+
array_fill(''::text, array[cardinality(coalesce(p.proallargtypes, p.proargtypes))])
16+
) as arg_names,
17+
-- proallargtypes is null when all arg modes are IN
18+
coalesce(p.proallargtypes, p.proargtypes) as arg_types
19+
from
20+
pg_proc as p
21+
where
22+
p.prokind = 'f'
23+
)
24+
select
25+
f.oid :: int8 as id,
26+
n.nspname as schema,
27+
f.proname as name,
28+
l.lanname as language,
29+
case
30+
when l.lanname = 'internal' then ''
31+
else f.prosrc
32+
end as definition,
33+
case
34+
when l.lanname = 'internal' then f.prosrc
35+
else pg_get_functiondef(f.oid)
36+
end as complete_statement,
37+
f_args.args as args,
38+
pg_get_function_arguments(f.oid) as argument_types,
39+
pg_get_function_identity_arguments(f.oid) as identity_argument_types,
40+
t.typname as return_type,
41+
case
42+
when f.provolatile = 'i' then 'IMMUTABLE'
43+
when f.provolatile = 's' then 'STABLE'
44+
when f.provolatile = 'v' then 'VOLATILE'
45+
end as behavior,
46+
f.prosecdef as security_definer,
47+
f_config.config_params as config_params
48+
from
49+
functions f
50+
left join pg_namespace n on f.pronamespace = n.oid
51+
left join pg_language l on f.prolang = l.oid
52+
left join pg_type t on t.oid = f.prorettype
53+
left join (
54+
select
55+
oid,
56+
jsonb_object_agg(param, value) filter (where param is not null) as config_params
57+
from
58+
(
59+
select
60+
oid,
61+
(string_to_array(unnest(proconfig), '='))[1] as param,
62+
(string_to_array(unnest(proconfig), '='))[2] as value
63+
from
64+
functions
65+
) as t
66+
group by
67+
oid
68+
) f_config on f_config.oid = f.oid
69+
left join (
70+
select
71+
oid,
72+
jsonb_agg(jsonb_build_object('mode', t2.mode, 'name', name, 'type_id', type_id)) as args
73+
from
74+
(
75+
select
76+
oid,
77+
unnest(arg_modes) as mode,
78+
unnest(arg_names) as name,
79+
unnest(arg_types)::int8 as type_id
80+
from
81+
functions
82+
) as t1,
83+
lateral (
84+
select
85+
case
86+
when t1.mode = 'i' then 'in'
87+
when t1.mode = 'o' then 'out'
88+
when t1.mode = 'b' then 'inout'
89+
when t1.mode = 'v' then 'variadic'
90+
else 'table'
91+
end as mode
92+
) as t2
93+
group by
94+
t1.oid
95+
) f_args on f_args.oid = f.oid

src/lib/types.ts

Lines changed: 13 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -82,6 +82,19 @@ const postgresFunctionSchema = Type.Object({
8282
language: Type.String(),
8383
definition: Type.String(),
8484
complete_statement: Type.String(),
85+
args: Type.Array(
86+
Type.Object({
87+
mode: Type.Union([
88+
Type.Literal('in'),
89+
Type.Literal('out'),
90+
Type.Literal('inout'),
91+
Type.Literal('variadic'),
92+
Type.Literal('table'),
93+
]),
94+
name: Type.String(),
95+
type_id: Type.Number(),
96+
})
97+
),
8598
argument_types: Type.String(),
8699
identity_argument_types: Type.String(),
87100
return_type: Type.String(),

test/lib/functions.ts

Lines changed: 62 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -6,6 +6,18 @@ test('list', async () => {
66
{ id: expect.any(Number) },
77
`
88
Object {
9+
"args": Array [
10+
Object {
11+
"mode": "in",
12+
"name": "",
13+
"type_id": 23,
14+
},
15+
Object {
16+
"mode": "in",
17+
"name": "",
18+
"type_id": 23,
19+
},
20+
],
921
"argument_types": "integer, integer",
1022
"behavior": "IMMUTABLE",
1123
"complete_statement": "CREATE OR REPLACE FUNCTION public.add(integer, integer)
@@ -49,6 +61,18 @@ test('retrieve, create, update, delete', async () => {
4961
`
5062
Object {
5163
"data": Object {
64+
"args": Array [
65+
Object {
66+
"mode": "in",
67+
"name": "a",
68+
"type_id": 21,
69+
},
70+
Object {
71+
"mode": "in",
72+
"name": "b",
73+
"type_id": 21,
74+
},
75+
],
5276
"argument_types": "a smallint, b smallint",
5377
"behavior": "STABLE",
5478
"complete_statement": "CREATE OR REPLACE FUNCTION public.test_func(a smallint, b smallint)
@@ -82,6 +106,18 @@ test('retrieve, create, update, delete', async () => {
82106
`
83107
Object {
84108
"data": Object {
109+
"args": Array [
110+
Object {
111+
"mode": "in",
112+
"name": "a",
113+
"type_id": 21,
114+
},
115+
Object {
116+
"mode": "in",
117+
"name": "b",
118+
"type_id": 21,
119+
},
120+
],
85121
"argument_types": "a smallint, b smallint",
86122
"behavior": "STABLE",
87123
"complete_statement": "CREATE OR REPLACE FUNCTION public.test_func(a smallint, b smallint)
@@ -119,14 +155,26 @@ test('retrieve, create, update, delete', async () => {
119155
`
120156
Object {
121157
"data": Object {
158+
"args": Array [
159+
Object {
160+
"mode": "in",
161+
"name": "a",
162+
"type_id": 21,
163+
},
164+
Object {
165+
"mode": "in",
166+
"name": "b",
167+
"type_id": 21,
168+
},
169+
],
122170
"argument_types": "a smallint, b smallint",
123171
"behavior": "STABLE",
124172
"complete_statement": "CREATE OR REPLACE FUNCTION test_schema.test_func_renamed(a smallint, b smallint)
125173
RETURNS integer
126174
LANGUAGE sql
127175
STABLE SECURITY DEFINER
128-
SET search_path TO 'hooks', 'auth'
129176
SET role TO 'postgres'
177+
SET search_path TO 'hooks', 'auth'
130178
AS $function$select b - a$function$
131179
",
132180
"config_params": Object {
@@ -152,14 +200,26 @@ test('retrieve, create, update, delete', async () => {
152200
`
153201
Object {
154202
"data": Object {
203+
"args": Array [
204+
Object {
205+
"mode": "in",
206+
"name": "a",
207+
"type_id": 21,
208+
},
209+
Object {
210+
"mode": "in",
211+
"name": "b",
212+
"type_id": 21,
213+
},
214+
],
155215
"argument_types": "a smallint, b smallint",
156216
"behavior": "STABLE",
157217
"complete_statement": "CREATE OR REPLACE FUNCTION test_schema.test_func_renamed(a smallint, b smallint)
158218
RETURNS integer
159219
LANGUAGE sql
160220
STABLE SECURITY DEFINER
161-
SET search_path TO 'hooks', 'auth'
162221
SET role TO 'postgres'
222+
SET search_path TO 'hooks', 'auth'
163223
AS $function$select b - a$function$
164224
",
165225
"config_params": Object {

0 commit comments

Comments
 (0)