|
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 |
0 commit comments