|
| 1 | +WITH column_data AS ( |
| 2 | + SELECT |
| 3 | + t.table_name, |
| 4 | + t.table_catalog, |
| 5 | + t.table_schema, |
| 6 | + c.column_name, |
| 7 | + TO_JSON_STRING(STRUCT( |
| 8 | + c.column_name AS name, |
| 9 | + JSON_OBJECT('ScalarType', |
| 10 | + case LOWER(c.data_type) |
| 11 | + when 'boolean' then 'boolean' |
| 12 | + when 'int16' then 'smallint' |
| 13 | + when 'smallint' then 'smallint' |
| 14 | + when 'int32' then 'integer' |
| 15 | + when 'integer' then 'integer' |
| 16 | + when 'int64' then 'bigint' |
| 17 | + when 'bigint' then 'bigint' |
| 18 | + when 'numeric' then 'numeric' |
| 19 | + when 'float64' then 'float' |
| 20 | + when 'float' then 'float' |
| 21 | + when 'real' then 'real' |
| 22 | + when 'double precision' then 'double precision' |
| 23 | + when 'text' then 'text' |
| 24 | + when 'string' then 'string' |
| 25 | + when 'character' then 'character' |
| 26 | + when 'json' then 'json' |
| 27 | + when 'jsonb' then 'jsonb' |
| 28 | + when 'date' then 'date' |
| 29 | + when 'time with time zone' then 'time with time zone' |
| 30 | + when 'time without time zone' then 'time without time zone' |
| 31 | + when 'timestamp with time zone' then 'timestamp with time zone' |
| 32 | + when 'timestamp without time zone' then 'timestamp without time zone' |
| 33 | + when 'uuid' then 'uuid' |
| 34 | + else 'any' |
| 35 | + end |
| 36 | + ) AS type, |
| 37 | + CASE WHEN c.is_nullable = 'YES' THEN 'nullable' ELSE 'nonNullable' END AS nullable |
| 38 | + )) AS column_info |
| 39 | + FROM hasura_database_name.INFORMATION_SCHEMA.TABLES AS t |
| 40 | + JOIN hasura_database_name.INFORMATION_SCHEMA.COLUMNS AS c |
| 41 | + ON c.table_catalog = t.table_catalog |
| 42 | + AND c.table_schema = t.table_schema |
| 43 | + AND c.table_name = t.table_name |
| 44 | + WHERE t.table_schema = 'chinook_sample' |
| 45 | +), |
| 46 | +columns_struct AS ( |
| 47 | + SELECT |
| 48 | + table_name, |
| 49 | + table_catalog, |
| 50 | + table_schema, |
| 51 | + STRUCT( |
| 52 | + STRING_AGG( |
| 53 | + CONCAT('"', column_name, '":', column_info), |
| 54 | + ',' |
| 55 | + ) AS columns_json |
| 56 | + ) AS columns |
| 57 | + FROM column_data |
| 58 | + GROUP BY table_name, table_catalog, table_schema |
| 59 | +), |
| 60 | +relationship_data AS ( |
| 61 | + SELECT |
| 62 | + t.table_name, |
| 63 | + t.table_catalog, |
| 64 | + t.table_schema, |
| 65 | + c.constraint_name, |
| 66 | + TO_JSON_STRING(STRUCT( |
| 67 | + rc.table_name AS foreign_table, |
| 68 | + json_object(fc.column_name, rc.column_name) as column_mapping |
| 69 | + )) AS relationship_info |
| 70 | + FROM hasura_database_name.INFORMATION_SCHEMA.TABLES AS t |
| 71 | + JOIN hasura_database_name.INFORMATION_SCHEMA.TABLE_CONSTRAINTS as c |
| 72 | + ON c.table_catalog = t.table_catalog |
| 73 | + AND c.table_schema = t.table_schema |
| 74 | + AND c.table_name = t.table_name |
| 75 | + JOIN hasura_database_name.INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE as rc |
| 76 | + ON c.constraint_catalog = rc.constraint_catalog |
| 77 | + AND c.constraint_schema = rc.constraint_schema |
| 78 | + AND c.constraint_name = rc.constraint_name |
| 79 | + JOIN hasura_database_name.INFORMATION_SCHEMA.KEY_COLUMN_USAGE as fc ON c.constraint_name = fc.constraint_name |
| 80 | + WHERE t.table_schema = 'chinook_sample' AND c.constraint_type = 'FOREIGN KEY' |
| 81 | + GROUP BY t.table_name, table_catalog, table_schema, constraint_name, rc.table_name, fc.column_name, rc.column_name |
| 82 | +), |
| 83 | +relationship_struct AS ( |
| 84 | + SELECT |
| 85 | + table_name, |
| 86 | + table_catalog, |
| 87 | + table_schema, |
| 88 | + STRUCT( |
| 89 | + STRING_AGG( |
| 90 | + CONCAT('"', constraint_name, '":', relationship_info), |
| 91 | + ',' |
| 92 | + ) AS relationships_json |
| 93 | + ) AS relationships |
| 94 | + FROM relationship_data |
| 95 | + GROUP BY table_name, table_catalog, table_schema |
| 96 | +), |
| 97 | +unique_constraint_data AS ( |
| 98 | + SELECT |
| 99 | + t.table_name, |
| 100 | + t.table_catalog, |
| 101 | + t.table_schema, |
| 102 | + c.constraint_name, |
| 103 | + TO_JSON_STRING(JSON_ARRAY(cc.column_name)) AS unique_constraint_info |
| 104 | + FROM hasura_database_name.INFORMATION_SCHEMA.TABLES AS t |
| 105 | + JOIN hasura_database_name.INFORMATION_SCHEMA.TABLE_CONSTRAINTS as c |
| 106 | + ON c.table_catalog = t.table_catalog |
| 107 | + AND c.table_schema = t.table_schema |
| 108 | + AND c.table_name = t.table_name |
| 109 | + JOIN hasura_database_name.INFORMATION_SCHEMA.CONSTRAINT_COLUMN_USAGE as cc |
| 110 | + ON c.constraint_name = cc.constraint_name |
| 111 | + WHERE t.table_schema = 'chinook_sample' |
| 112 | + AND c.constraint_type in ('PRIMARY KEY', 'UNIQUE') |
| 113 | + AND cc.constraint_catalog = c.constraint_catalog |
| 114 | + AND cc.constraint_schema = c.constraint_schema |
| 115 | +), |
| 116 | +unique_constraint_struct AS ( |
| 117 | + SELECT |
| 118 | + table_name, |
| 119 | + table_catalog, |
| 120 | + table_schema, |
| 121 | + STRUCT( |
| 122 | + STRING_AGG( |
| 123 | + CONCAT('"', constraint_name, '":', unique_constraint_info), |
| 124 | + ',' |
| 125 | + ) AS unique_constraint_json |
| 126 | + ) AS unique_constraint |
| 127 | + FROM unique_constraint_data |
| 128 | + GROUP BY table_name, table_catalog, table_schema |
| 129 | +) |
| 130 | +SELECT |
| 131 | + CONCAT('{', STRING_AGG(CONCAT( |
| 132 | + '"', columns_struct.table_name, '": {', |
| 133 | + '"schemaName": ', |
| 134 | + '"', CONCAT(columns_struct.table_catalog , '.', columns_struct.table_schema), '", ', |
| 135 | + '"tableName": ' , '"', columns_struct.table_name, '", ' |
| 136 | + '"columns": {', |
| 137 | + columns_struct.columns.columns_json, |
| 138 | + '},', |
| 139 | + '"uniquenessConstraints": {', |
| 140 | + coalesce(unique_constraint_struct.unique_constraint.unique_constraint_json, ""), |
| 141 | + '},', |
| 142 | + '"foreignRelations": {', |
| 143 | + coalesce(relationship_struct.relationships.relationships_json, ""), |
| 144 | + '}' |
| 145 | + '}' |
| 146 | + )), '}') AS result |
| 147 | +FROM columns_struct |
| 148 | +LEFT JOIN relationship_struct ON columns_struct.table_name = relationship_struct.table_name |
| 149 | +LEFT JOIN unique_constraint_struct ON columns_struct.table_name = unique_constraint_struct.table_name |
0 commit comments