--select * from dropall('meta.get_table_fields'); CREATE OR REPLACE FUNCTION meta.get_table_fields( p_schema_name text ,p_table_name text ) RETURNS JSONB LANGUAGE plpgsql STABLE cost 10 SECURITY DEFINER AS $$ DECLARE a_primary_keys citext[]; a_foreign_keys citext[]; BEGIN SELECT array_agg(kcu.column_name::citext) FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.constraint_type = 'PRIMARY KEY' AND tc.table_schema = p_schema_name::citext AND tc.table_name = p_table_name::citext INTO a_primary_keys ; SELECT array_agg(kcu.column_name::citext) FROM information_schema.table_constraints tc JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema WHERE tc.constraint_type = 'FOREIGN KEY' AND tc.table_schema = p_schema_name::citext AND tc.table_name = p_table_name::citext INTO a_foreign_keys ; return ( SELECT jsonb_object_agg(col.column_name::citext , jsonb_build_object( 'type', case when col.data_type::citext = 'USER-DEFINED' then col.udt_name::citext else col.data_type::citext end , 'primary_key', case when col.column_name = any (a_primary_keys) then true else false end , 'foreign_key', case when col.column_name = any (a_foreign_keys) then true else false end ,'relation', ( select to_jsonb(r) from ( SELECT DISTINCT c.table_schema AS parent_schema , c.table_name AS parent_table , cc.column_name AS parent_column --, kcu.column_name AS relation_column FROM information_schema.table_constraints tc JOIN information_schema.constraint_column_usage ccu ON tc.constraint_name = ccu.constraint_name AND tc.table_schema = ccu.table_schema JOIN information_schema.key_column_usage kcu ON tc.constraint_name = kcu.constraint_name AND tc.table_schema = kcu.table_schema JOIN information_schema.referential_constraints rc ON tc.constraint_name = rc.constraint_name JOIN information_schema.constraint_column_usage cc ON rc.unique_constraint_name = cc.constraint_name JOIN information_schema.constraint_table_usage c ON rc.unique_constraint_name = c.constraint_name WHERE tc.constraint_type = 'FOREIGN KEY' AND tc.table_schema = p_schema_name::citext AND tc.table_name = p_table_name::citext and kcu.column_name = col.column_name ) r ) ) ) FROM information_schema.columns col WHERE col.table_schema = p_schema_name::citext AND col.table_name = p_table_name::citext ); END; $$; --select meta.get_table_fields('core','masterprocess')