From 2a943d6bbfd1a178924db7f4eddcba88644501b1 Mon Sep 17 00:00:00 2001 From: Laurence Isla Date: Mon, 2 Sep 2024 12:33:26 -0500 Subject: [PATCH] refactor: make the function that queries all tables more reusable - Merges postgrest_get_all_tables and postgrest_get_all_composite_types - Removes the need of using unnest(), making the queries a bit more performant --- sql/components.sql | 105 ++++++--- sql/paths.sql | 8 +- sql/postgrest.sql | 555 +++++++++++---------------------------------- 3 files changed, 209 insertions(+), 459 deletions(-) diff --git a/sql/components.sql b/sql/components.sql index 0ef300e..a14fe86 100644 --- a/sql/components.sql +++ b/sql/components.sql @@ -17,40 +17,84 @@ $$; create or replace function oas_build_component_schemas(schemas text[]) returns jsonb language sql stable as $$ - select oas_build_component_schemas_from_tables(schemas) || - oas_build_component_schemas_from_composite_types(schemas) || + select oas_build_component_schemas_from_tables_and_composite_types(schemas) || oas_build_component_schemas_headers() $$; -create or replace function oas_build_component_schemas_from_tables(schemas text[]) +create or replace function oas_build_component_schemas_from_tables_and_composite_types(schemas text[]) returns jsonb language sql stable as $$ -select jsonb_object_agg(x.table_name, x.oas_schema) +with recursive all_rels as ( + select * + from postgrest_get_all_tables_and_composite_types() +), +recursive_rels_in_schema as ( + select * + from all_rels + where + -- All the tables or views in the exposed schemas + (table_schema = any(schemas) and (is_table or is_view)) + -- All the composite types or tables that are present in function arguments + -- TODO: tweak postgrest_get_all_functions() or use another CTE for a more performant filter + or table_oid in ( + select unnest(composite_args_ret) + from postgrest_get_all_functions(schemas) + ) + union + -- Tables may have columns with composite or table types, so we recursively + -- look for these composite types or tables outside of the exposed schemas + -- in order to build the types correctly for the OpenAPI output. + select e.* + from all_rels e, recursive_rels_in_schema r + where e.table_oid = r.column_composite_relid +), +all_tables_and_composite_types as ( + select + table_schema, + table_name, + table_description, + is_composite, + array_agg(column_name order by column_position) filter (where not column_is_nullable) AS required_cols, + jsonb_object_agg( + column_name, + case when column_item_data_type is null and column_composite_relid <> 0 then + oas_build_reference_to_schemas(column_data_type) + else + oas_schema_object( + description := column_description, + type := postgrest_pgtype_to_oastype(column_data_type), + format := column_data_type::text, + maxlength := column_character_maximum_length, + -- "default" := to_jsonb(info.column_default), + enum := to_jsonb(column_enums), + items := + case + when column_item_data_type is null then + null + when column_composite_relid <> 0 then + oas_build_reference_to_schemas(column_item_data_type) + else + oas_schema_object( + type := postgrest_pgtype_to_oastype(column_item_data_type), + format := column_item_data_type::text + ) + end + ) + end order by column_position + ) as columns + from recursive_rels_in_schema + group by table_schema, table_name, table_description, is_composite +) +select jsonb_object_agg(x.component_name, x.oas_schema) from ( - select table_name, + select case when is_composite then table_schema || '.' else '' end || table_name as component_name, oas_schema_object( description := table_description, - properties := columns, + properties := coalesce(columns, '{}'), required := required_cols, type := 'object' ) as oas_schema - from postgrest_get_all_tables(schemas) - where table_schema = any(schemas) -) x; -$$; - -create or replace function oas_build_component_schemas_from_composite_types(schemas text[]) -returns jsonb language sql stable as -$$ -SELECT coalesce(jsonb_object_agg(x.ct_name, x.oas_schema), '{}') -FROM ( - SELECT comptype_schema || '.' || comptype_name as ct_name, - oas_schema_object( - description := comptype_description, - properties := columns, - type := 'object' - ) AS oas_schema - FROM postgrest_get_all_composite_types(schemas) + from all_tables_and_composite_types ) x; $$; @@ -195,10 +239,11 @@ from ( ) ) as param_schema from ( - select table_schema, table_name, unnest(all_cols) as column_name - from postgrest_get_all_tables(schemas) + select table_schema, is_table, is_view, table_name, column_name + from postgrest_get_all_tables_and_composite_types() + where table_schema = any(schemas) + and (is_table or is_view) ) _ - where table_schema = any(schemas) ) x; $$; @@ -617,8 +662,10 @@ from ( ) ) end as may_be_empty_response - from postgrest_get_all_tables(schemas) + from postgrest_get_all_tables_and_composite_types() where table_schema = any(schemas) + and (is_table or is_view) + group by table_schema, table_name, insertable, is_table, is_view ) as x $$; @@ -695,9 +742,11 @@ from ( ) ) ) as oas_req_body - from postgrest_get_all_tables(schemas) + from postgrest_get_all_tables_and_composite_types() where table_schema = any(schemas) + and (is_table or is_view) and insertable + group by table_schema, table_name, insertable ) as x; $$; diff --git a/sql/paths.sql b/sql/paths.sql index 70d0bb0..7b94174 100644 --- a/sql/paths.sql +++ b/sql/paths.sql @@ -124,10 +124,12 @@ from ( end ) as oas_path_item from ( - select table_schema, table_name, table_description, insertable, updatable, deletable, unnest(all_cols) as column_name - from postgrest_get_all_tables(schemas) + select table_schema, table_name, table_description, insertable, updatable, deletable, column_name + from postgrest_get_all_tables_and_composite_types() + where table_schema = any(schemas) + and (is_table or is_view) + order by table_schema, table_name, column_position ) _ - where table_schema = any(schemas) group by table_schema, table_name, table_description, insertable, updatable, deletable ) x; $$; diff --git a/sql/postgrest.sql b/sql/postgrest.sql index 82ae7e0..922ee64 100644 --- a/sql/postgrest.sql +++ b/sql/postgrest.sql @@ -1,458 +1,157 @@ -- Functions to get information from PostgREST to generate the OpenAPI output --- TODO: simplify the query to have only relevant info for OpenAPI --- TODO: to keep it reusable it may need to return data as is without using OAS objects. --- To do so, "columns" has to be normalized (not a JSON aggregate) -create or replace function postgrest_get_all_tables(schemas text[]) +create or replace function postgrest_get_all_tables_and_composite_types() returns table ( + column_name text, + column_description text, + column_default text, + column_is_nullable bool, + column_data_type text, + column_item_data_type text, + column_character_maximum_length integer, + column_enums text[], + column_composite_relid oid, + column_position int, + column_is_pk bool, + table_oid oid, + table_namespace oid, table_schema text, table_name text, table_description text, + is_table bool, is_view bool, + is_composite bool, insertable bool, updatable bool, - deletable bool, - pk_cols text[], - composite_cols oid[], - required_cols text[], - all_cols text[], - columns jsonb + deletable bool ) language sql stable as $$ -WITH - columns AS ( - SELECT - nc.nspname::name AS table_schema, - c.relname::name AS table_name, - a.attname::name AS column_name, - d.description AS description, - CASE - WHEN a.attidentity = 'd' THEN format('nextval(%s)', quote_literal(seqsch.nspname || '.' || seqclass.relname)) - WHEN a.attgenerated = 's' THEN null - ELSE pg_get_expr(ad.adbin, ad.adrelid)::text - END AS column_default, - not (a.attnotnull OR t.typtype = 'd' AND t.typnotnull) AS is_nullable, - t.typarray = 0 AS is_array, - t.typtype = 'c' AS is_composite, - t.typrelid AS composite_oid, - CASE - WHEN t.typtype = 'd' THEN - CASE - WHEN nbt.nspname = 'pg_catalog'::name THEN format_type(t.typbasetype, NULL::integer) - ELSE format_type(a.atttypid, a.atttypmod) - END - ELSE - CASE - WHEN nt.nspname = 'pg_catalog'::name THEN format_type(a.atttypid, NULL::integer) - ELSE format_type(a.atttypid, a.atttypmod) - END - END::text AS data_type, - t.oid AS data_type_id, - information_schema._pg_char_max_length( - information_schema._pg_truetypid(a.*, t.*), - information_schema._pg_truetypmod(a.*, t.*) - )::integer AS character_maximum_length, - COALESCE(bt.typname, t.typname)::name AS udt_name, - a.attnum::integer AS position, - CASE - WHEN t_arr.typtype = 'd' THEN - CASE - WHEN nbt_arr.nspname = 'pg_catalog'::name THEN format_type(t_arr.typbasetype, NULL::integer) - ELSE format_type(t_arr.oid, t_arr.typtypmod) - END - ELSE - CASE - WHEN nt_arr.nspname = 'pg_catalog'::name THEN format_type(t_arr.oid, NULL::integer) - ELSE format_type(t_arr.oid, t_arr.typtypmod) - END - END::text AS item_data_type, - t_arr.typtype = 'c' AS item_is_composite, - t_arr.typrelid AS item_composite_oid, - t_arr.oid AS item_data_type_id - FROM pg_attribute a - LEFT JOIN pg_description AS d - ON d.objoid = a.attrelid and d.objsubid = a.attnum - LEFT JOIN pg_attrdef ad - ON a.attrelid = ad.adrelid AND a.attnum = ad.adnum - JOIN (pg_class c JOIN pg_namespace nc ON c.relnamespace = nc.oid) - ON a.attrelid = c.oid - JOIN (pg_type t JOIN pg_namespace nt ON t.typnamespace = nt.oid) - ON a.atttypid = t.oid - LEFT JOIN (pg_type bt JOIN pg_namespace nbt ON bt.typnamespace = nbt.oid) - ON t.typtype = 'd' AND t.typbasetype = bt.oid - LEFT JOIN (pg_type t_arr JOIN pg_namespace nt_arr ON t_arr.typnamespace = nt_arr.oid) - ON t.oid = t_arr.typarray - LEFT JOIN (pg_type bt_arr JOIN pg_namespace nbt_arr ON bt_arr.typnamespace = nbt_arr.oid) - ON t_arr.typtype = 'd' AND t_arr.typbasetype = bt_arr.oid - LEFT JOIN (pg_collation co JOIN pg_namespace nco ON co.collnamespace = nco.oid) - ON a.attcollation = co.oid AND (nco.nspname <> 'pg_catalog'::name OR co.collname <> 'default'::name) - LEFT JOIN pg_depend dep - ON dep.refobjid = a.attrelid and dep.refobjsubid = a.attnum and dep.deptype = 'i' - LEFT JOIN pg_class seqclass - ON seqclass.oid = dep.objid - LEFT JOIN pg_namespace seqsch - ON seqsch.oid = seqclass.relnamespace - WHERE - NOT pg_is_other_temp_schema(nc.oid) - AND a.attnum > 0 - AND NOT a.attisdropped - AND c.relkind in ('r', 'v', 'f', 'm', 'p') - AND nc.nspname = ANY(schemas) - ), - columns_agg AS ( - SELECT DISTINCT - info.table_schema AS table_schema, - info.table_name AS table_name, - array_agg(coalesce(info.composite_oid, info.item_composite_oid)) filter (where info.is_composite or info.item_is_composite) AS composite_cols, - array_agg(info.column_name order by info.position) filter (where not info.is_nullable) AS required_cols, - array_agg(info.column_name order by info.position) AS all_cols, - jsonb_object_agg( - info.column_name, - case when info.is_composite then - oas_build_reference_to_schemas(info.data_type) - else - oas_schema_object( - description := info.description, - type := postgrest_pgtype_to_oastype(info.data_type), - format := info.data_type::text, - maxlength := info.character_maximum_length, - -- "default" := to_jsonb(info.column_default), - enum := to_jsonb(enum_info.vals), - items := - case - when not info.is_array then - null - when info.item_is_composite then - oas_build_reference_to_schemas(info.item_data_type) - else - oas_schema_object( - type := postgrest_pgtype_to_oastype(info.item_data_type), - format := info.item_data_type::text - ) - end - ) - end order by info.position - ) as columns - FROM columns info - LEFT OUTER JOIN ( - SELECT - n.nspname AS s, - t.typname AS n, - array_agg(e.enumlabel ORDER BY e.enumsortorder) AS vals - FROM pg_type t - JOIN pg_enum e ON t.oid = e.enumtypid - JOIN pg_namespace n ON n.oid = t.typnamespace - GROUP BY s,n - ) AS enum_info ON info.udt_name = enum_info.n - WHERE info.table_schema NOT IN ('pg_catalog', 'information_schema') - GROUP BY info.table_schema, info.table_name - ), - tbl_constraints AS ( - SELECT - c.conname::name AS constraint_name, - nr.nspname::name AS table_schema, - r.relname::name AS table_name - FROM pg_namespace nc - JOIN pg_constraint c ON nc.oid = c.connamespace - JOIN pg_class r ON c.conrelid = r.oid - JOIN pg_namespace nr ON nr.oid = r.relnamespace - WHERE - r.relkind IN ('r', 'p') - AND NOT pg_is_other_temp_schema(nr.oid) - AND c.contype = 'p' - ), - key_col_usage AS ( - SELECT - ss.conname::name AS constraint_name, - ss.nr_nspname::name AS table_schema, - ss.relname::name AS table_name, - a.attname::name AS column_name, - (ss.x).n::integer AS ordinal_position, - CASE - WHEN ss.contype = 'f' THEN information_schema._pg_index_position(ss.conindid, ss.confkey[(ss.x).n]) - ELSE NULL::integer - END::integer AS position_in_unique_constraint - FROM pg_attribute a - JOIN ( - SELECT r.oid AS roid, - r.relname, - r.relowner, - nc.nspname AS nc_nspname, - nr.nspname AS nr_nspname, - c.oid AS coid, - c.conname, - c.contype, - c.conindid, - c.confkey, - information_schema._pg_expandarray(c.conkey) AS x - FROM pg_namespace nr - JOIN pg_class r - ON nr.oid = r.relnamespace - JOIN pg_constraint c - ON r.oid = c.conrelid - JOIN pg_namespace nc - ON c.connamespace = nc.oid - WHERE - c.contype in ('p', 'u') - AND r.relkind IN ('r', 'p') - AND NOT pg_is_other_temp_schema(nr.oid) - ) ss ON a.attrelid = ss.roid AND a.attnum = (ss.x).x - WHERE - NOT a.attisdropped - ), +WITH RECURSIVE tbl_pk_cols AS ( SELECT - key_col_usage.table_schema, - key_col_usage.table_name, - array_agg(key_col_usage.column_name) as pk_cols - FROM - tbl_constraints - JOIN - key_col_usage - ON - key_col_usage.table_name = tbl_constraints.table_name AND - key_col_usage.table_schema = tbl_constraints.table_schema AND - key_col_usage.constraint_name = tbl_constraints.constraint_name + r.oid AS relid, + a.attnum AS position + FROM pg_class r + JOIN pg_constraint c + ON r.oid = c.conrelid + JOIN pg_attribute a + ON a.attrelid = r.oid AND a.attnum = ANY (c.conkey) WHERE - key_col_usage.table_schema NOT IN ('pg_catalog', 'information_schema') - GROUP BY key_col_usage.table_schema, key_col_usage.table_name + c.contype in ('p') + AND r.relkind IN ('r', 'p') + AND r.relnamespace NOT IN ('pg_catalog'::regnamespace, 'information_schema'::regnamespace) + AND NOT pg_is_other_temp_schema(r.relnamespace) + AND NOT a.attisdropped + GROUP BY r.oid, a.attnum ) -SELECT - n.nspname AS table_schema, - c.relname AS table_name, - d.description AS table_description, - c.relkind IN ('v','m') as is_view, - ( - c.relkind IN ('r','p') - OR ( - c.relkind in ('v','f') - -- The function `pg_relation_is_updateable` returns a bitmask where 8 - -- corresponds to `1 << CMD_INSERT` in the PostgreSQL source code, i.e. - -- it's possible to insert into the relation. - AND (pg_relation_is_updatable(c.oid::regclass, TRUE) & 8) = 8 - ) - ) AS insertable, - ( - c.relkind IN ('r','p') - OR ( - c.relkind in ('v','f') - -- CMD_UPDATE - AND (pg_relation_is_updatable(c.oid::regclass, TRUE) & 4) = 4 - ) - ) AS updatable, - ( - c.relkind IN ('r','p') - OR ( - c.relkind in ('v','f') - -- CMD_DELETE - AND (pg_relation_is_updatable(c.oid::regclass, TRUE) & 16) = 16 - ) - ) AS deletable, - coalesce(tpks.pk_cols, '{}') as pk_cols, - cols_agg.composite_cols, - cols_agg.required_cols, - cols_agg.all_cols, - coalesce(cols_agg.columns, '{}') as columns -FROM pg_class c - JOIN pg_namespace n ON n.oid = c.relnamespace - LEFT JOIN pg_description d on d.objoid = c.oid and d.objsubid = 0 - LEFT JOIN tbl_pk_cols tpks ON n.nspname = tpks.table_schema AND c.relname = tpks.table_name - LEFT JOIN columns_agg cols_agg ON n.nspname = cols_agg.table_schema AND c.relname = cols_agg.table_name -WHERE c.relkind IN ('v','r','m','f','p') - AND n.nspname NOT IN ('pg_catalog', 'information_schema') - AND not c.relispartition -ORDER BY table_schema, table_name; -$$; - --- TODO: This function could be integrated in postgrest_get_all_tables -create or replace function postgrest_get_all_composite_types(schemas text[]) -returns table ( - comptype_schema text, - comptype_name text, - comptype_description text, - columns jsonb -) language sql stable as -$$ -WITH - columns AS ( - SELECT - nc.nspname::name AS comptype_schema, - c.relname::name AS comptype_name, - a.attname::name AS column_name, - d.description AS description, - t.typarray = 0 AS is_array, - t.typtype = 'c' AS is_composite, - CASE + SELECT + a.attname::name AS column_name, + d.description AS column_description, + -- typbasetype and typdefaultbin handles `CREATE DOMAIN .. DEFAULT val`, attidentity/attgenerated handles generated columns, pg_get_expr gets the default of a column + CASE + WHEN t.typbasetype != 0 THEN pg_get_expr(t.typdefaultbin, 0) + WHEN a.attidentity = 'd' THEN format('nextval(%L)', seq.objid::regclass) + WHEN a.attgenerated = 's' THEN null + ELSE pg_get_expr(ad.adbin, ad.adrelid)::text + END AS column_default, + NOT (a.attnotnull OR t.typtype = 'd' AND t.typnotnull) AS is_nullable, + CASE WHEN t.typtype = 'd' THEN - CASE - WHEN nbt.nspname = 'pg_catalog'::name THEN format_type(t.typbasetype, NULL::integer) + CASE + WHEN bt.typnamespace = 'pg_catalog'::regnamespace THEN format_type(t.typbasetype, NULL::integer) ELSE format_type(a.atttypid, a.atttypmod) - END + END ELSE - CASE - WHEN nt.nspname = 'pg_catalog'::name THEN format_type(a.atttypid, NULL::integer) + CASE + WHEN t.typnamespace = 'pg_catalog'::regnamespace THEN format_type(a.atttypid, NULL::integer) ELSE format_type(a.atttypid, a.atttypmod) - END - END::text AS data_type, - t.oid AS data_type_id, - information_schema._pg_char_max_length( - information_schema._pg_truetypid(a.*, t.*), - information_schema._pg_truetypmod(a.*, t.*) - )::integer AS character_maximum_length, - COALESCE(bt.typname, t.typname)::name AS udt_name, - a.attnum::integer AS position, - CASE + END + END::text AS column_data_type, + CASE WHEN t_arr.typtype = 'd' THEN - CASE - WHEN nbt_arr.nspname = 'pg_catalog'::name THEN format_type(t_arr.typbasetype, NULL::integer) + CASE + WHEN bt_arr.typnamespace = 'pg_catalog'::regnamespace THEN format_type(t_arr.typbasetype, NULL::integer) ELSE format_type(t_arr.oid, t_arr.typtypmod) - END + END ELSE - CASE - WHEN nt_arr.nspname = 'pg_catalog'::name THEN format_type(t_arr.oid, NULL::integer) + CASE + WHEN t_arr.typnamespace = 'pg_catalog'::regnamespace THEN format_type(t_arr.oid, NULL::integer) ELSE format_type(t_arr.oid, t_arr.typtypmod) - END - END::text AS item_data_type, - t_arr.typtype = 'c' AS item_is_composite, - t_arr.typrelid AS item_comptype_id, - t_arr.oid AS item_data_type_id, - -- Used for the recursive query - a.attrelid AS comptype_id, - t.typrelid AS column_comptype_id - FROM pg_attribute a - LEFT JOIN pg_description AS d + END + END::text AS column_item_data_type, + information_schema._pg_char_max_length( + information_schema._pg_truetypid(a.*, t.*), + information_schema._pg_truetypmod(a.*, t.*) + )::integer AS column_character_maximum_length, + (SELECT array_agg(enumlabel ORDER BY enumsortorder) FROM pg_enum WHERE enumtypid = COALESCE(COALESCE(bt_arr.oid, bt.oid), COALESCE(t_arr.oid, t.oid))) AS column_enums, + -- If the column or item is a composite type, this references the relid. + COALESCE(COALESCE(bt_arr.typrelid, t_arr.typrelid), COALESCE(bt.typrelid, t.typrelid)) AS column_composite_relid, + a.attnum::integer AS position, + tpks.position IS NOT NULL AS column_is_pk, + c.oid AS table_oid, + c.relnamespace AS table_namespace, + n.nspname AS table_schema, + c.relname AS table_name, + td.description AS table_description, + c.relkind IN ('r','f','p') AS is_table, + c.relkind IN ('v','m') AS is_view, + c.relkind IN ('c') AS is_composite, + ( + c.relkind IN ('r','p') + OR ( + c.relkind in ('v','f') + -- The function `pg_relation_is_updateable` returns a bitmask where 8 + -- corresponds to `1 << CMD_INSERT` in the PostgreSQL source code, i.e. + -- it's possible to insert into the relation. + AND (pg_relation_is_updatable(c.oid::regclass, TRUE) & 8) = 8 + ) + ) AS insertable, + ( + c.relkind IN ('r','p') + OR ( + c.relkind in ('v','f') + -- CMD_UPDATE + AND (pg_relation_is_updatable(c.oid::regclass, TRUE) & 4) = 4 + ) + ) AS updatable, + ( + c.relkind IN ('r','p') + OR ( + c.relkind in ('v','f') + -- CMD_DELETE + AND (pg_relation_is_updatable(c.oid::regclass, TRUE) & 16) = 16 + ) + ) AS deletable + FROM pg_attribute a + LEFT JOIN pg_description AS d ON d.objoid = a.attrelid and d.objsubid = a.attnum - JOIN (pg_class c JOIN pg_namespace nc ON c.relnamespace = nc.oid) + LEFT JOIN pg_attrdef ad + ON a.attrelid = ad.adrelid AND a.attnum = ad.adnum + JOIN pg_class c ON a.attrelid = c.oid - JOIN (pg_type t JOIN pg_namespace nt ON t.typnamespace = nt.oid) + JOIN pg_namespace n + ON n.oid = c.relnamespace + LEFT JOIN pg_description AS td + ON td.objoid = CASE WHEN c.relkind = 'c' then c.reltype else c.oid end AND td.objsubid = 0 + JOIN pg_type t ON a.atttypid = t.oid - LEFT JOIN (pg_type bt JOIN pg_namespace nbt ON bt.typnamespace = nbt.oid) + LEFT JOIN pg_type t_arr + ON t.typarray = 0 AND t.oid = t_arr.typarray + LEFT JOIN pg_type bt ON t.typtype = 'd' AND t.typbasetype = bt.oid - LEFT JOIN (pg_type t_arr JOIN pg_namespace nt_arr ON t_arr.typnamespace = nt_arr.oid) - ON t.oid = t_arr.typarray - LEFT JOIN (pg_type bt_arr JOIN pg_namespace nbt_arr ON bt_arr.typnamespace = nbt_arr.oid) - ON t_arr.typtype = 'd' AND t_arr.typbasetype = bt_arr.oid - LEFT JOIN (pg_collation co JOIN pg_namespace nco ON co.collnamespace = nco.oid) - ON a.attcollation = co.oid AND (nco.nspname <> 'pg_catalog'::name OR co.collname <> 'default'::name) - LEFT JOIN pg_depend dep - ON dep.refobjid = a.attrelid and dep.refobjsubid = a.attnum and dep.deptype = 'i' - LEFT JOIN pg_class seqclass - ON seqclass.oid = dep.objid - LEFT JOIN pg_namespace seqsch - ON seqsch.oid = seqclass.relnamespace - WHERE - NOT pg_is_other_temp_schema(nc.oid) - AND a.attnum > 0 - AND NOT a.attisdropped - AND c.relkind = 'c' - ), - all_comptype_columns AS ( - -- TODO: This may repeat cycles,verify if UNION is performant enough - WITH RECURSIVE recurse AS ( - SELECT - comptype_schema, - comptype_name, - column_name, - description, - is_array, - is_composite, - data_type, - data_type_id, - character_maximum_length, - udt_name, - position, - comptype_id, - column_comptype_id, - item_data_type, - item_is_composite, - item_comptype_id - FROM columns - -- List only the the composite types that are used by tables and functions in the exposed schema - WHERE comptype_id in ( - select unnest(composite_cols) from postgrest_get_all_tables(schemas) - union - select unnest(composite_args_ret) from postgrest_get_all_functions(schemas) - ) - UNION - SELECT - c.comptype_schema, - c.comptype_name, - c.column_name, - c.description, - c.is_array, - c.is_composite, - c.data_type, - c.data_type_id, - c.character_maximum_length, - c.udt_name, - c.position, - c.comptype_id, - c.column_comptype_id, - c.item_data_type, - c.item_is_composite, - c.item_comptype_id - FROM columns c - JOIN recurse r on c.comptype_id = coalesce(r.item_comptype_id, r.column_comptype_id) - ) - SELECT * FROM recurse - ), - columns_agg AS ( - SELECT DISTINCT - info.comptype_schema AS comptype_schema, - info.comptype_name AS comptype_name, - array_agg(coalesce(info.data_type_id, info.item_comptype_id)) filter (where info.is_composite or info.item_is_composite) AS composite_cols, - jsonb_object_agg( - info.column_name, - case when info.is_composite then - oas_build_reference_to_schemas(info.data_type) - else - oas_schema_object( - description := info.description, - type := postgrest_pgtype_to_oastype(info.data_type), - format := info.data_type::text, - maxlength := info.character_maximum_length, - -- "default" := to_jsonb(info.column_default), - enum := to_jsonb(enum_info.vals), - items := - case - when not info.is_array then - null - when info.item_is_composite then - oas_build_reference_to_schemas(info.item_data_type) - else - oas_schema_object( - type := postgrest_pgtype_to_oastype(info.item_data_type), - format := info.item_data_type::text - ) - end - ) - end order by info.position - ) as columns - FROM all_comptype_columns info - LEFT OUTER JOIN ( - SELECT - n.nspname AS s, - t.typname AS n, - array_agg(e.enumlabel ORDER BY e.enumsortorder) AS vals - FROM pg_type t - JOIN pg_enum e ON t.oid = e.enumtypid - JOIN pg_namespace n ON n.oid = t.typnamespace - GROUP BY s,n - ) AS enum_info ON info.udt_name = enum_info.n - WHERE info.comptype_schema NOT IN ('pg_catalog', 'information_schema') - GROUP BY info.comptype_schema, info.comptype_name - ) -SELECT - n.nspname AS comptype_schema, - c.relname AS comptype_name, - d.description AS comptype_description, - coalesce(cols_agg.columns, '{}') as columns -FROM pg_class c - JOIN pg_namespace n ON n.oid = c.relnamespace - LEFT JOIN pg_description d on d.objoid = c.reltype and d.objsubid = 0 - JOIN columns_agg cols_agg ON n.nspname = cols_agg.comptype_schema AND c.relname = cols_agg.comptype_name -WHERE c.relkind = 'c' - AND n.nspname NOT IN ('pg_catalog', 'information_schema'); + LEFT JOIN pg_type bt_arr + ON bt.typarray = 0 AND bt.oid = bt_arr.typarray + LEFT JOIN pg_depend seq + ON seq.refobjid = a.attrelid AND seq.refobjsubid = a.attnum and seq.deptype = 'i' + LEFT JOIN tbl_pk_cols tpks + ON c.oid = tpks.relid AND a.attrelid = tpks.position + WHERE + NOT pg_is_other_temp_schema(c.relnamespace) + AND a.attnum > 0 + AND NOT a.attisdropped + AND c.relkind in ('r', 'v', 'f', 'm', 'p', 'c') + AND c.relnamespace NOT IN ('pg_catalog'::regnamespace, 'information_schema'::regnamespace) + AND not c.relispartition; $$; -- TODO: simplify the query to have only relevant info for OpenAPI