|
| 1 | + |
| 2 | +-- dd."schemas" source |
| 3 | + |
| 4 | +DROP VIEW dd."schemas"; |
| 5 | + |
| 6 | +CREATE VIEW dd."schemas" |
| 7 | +AS WITH s AS ( |
| 8 | + SELECT n.oid, |
| 9 | + n.nspname AS s_name, |
| 10 | + pg_get_userbyid(n.nspowner) AS owner, |
| 11 | + ms.data_source, |
| 12 | + ms.sensitive, |
| 13 | + obj_description(n.oid, 'pg_namespace'::name) AS description, |
| 14 | + CASE WHEN n.nspname !~ '^pg_'::text |
| 15 | + AND (n.nspname <> ALL (ARRAY['pg_catalog'::name, 'information_schema'::name])) |
| 16 | + THEN False |
| 17 | + ELSE True |
| 18 | + END AS system_object |
| 19 | + FROM pg_namespace n |
| 20 | + LEFT JOIN dd.meta_schema ms ON n.nspname = ms.s_name |
| 21 | + ), |
| 22 | + f AS ( |
| 23 | + SELECT n.nspname AS s_name, COUNT(DISTINCT p.oid) AS function_count |
| 24 | + FROM pg_catalog.pg_proc p |
| 25 | + INNER JOIN pg_catalog.pg_namespace n ON n.oid = p.pronamespace |
| 26 | + GROUP BY n.nspname |
| 27 | + ), |
| 28 | + v AS ( |
| 29 | + SELECT n.nspname AS s_name, COUNT(DISTINCT c.oid) AS view_count |
| 30 | + FROM pg_catalog.pg_class c |
| 31 | + INNER JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace |
| 32 | + WHERE c.relkind IN ('v', 'm') |
| 33 | + GROUP BY n.nspname |
| 34 | + ) |
| 35 | + SELECT s.s_name, |
| 36 | + s.owner, |
| 37 | + s.data_source, |
| 38 | + s.sensitive, |
| 39 | + s.description, |
| 40 | + s.system_object, |
| 41 | + COALESCE(COUNT(c.*), 0::BIGINT)::BIGINT AS table_count, |
| 42 | + COALESCE(v.view_count, 0)::BIGINT AS view_count, |
| 43 | + COALESCE(f.function_count, 0)::BIGINT AS function_count, |
| 44 | + pg_size_pretty(SUM(pg_table_size(c.oid::regclass))) AS size_pretty, |
| 45 | + pg_size_pretty(SUM(pg_total_relation_size(c.oid::regclass))) AS size_plus_indexes, |
| 46 | + SUM(pg_table_size(c.oid::regclass)) AS size_bytes |
| 47 | + FROM s |
| 48 | + LEFT JOIN pg_class c ON s.oid = c.relnamespace AND (c.relkind = ANY (ARRAY['r'::"char", 'p'::"char"])) |
| 49 | + LEFT JOIN f ON f.s_name = s.s_name |
| 50 | + LEFT JOIN v ON v.s_name = s.s_name |
| 51 | + GROUP BY s.s_name, s.owner, s.data_source, |
| 52 | + s.sensitive, s.description, s.system_object, |
| 53 | + v.view_count, f.function_count |
| 54 | + ; |
| 55 | + |
| 56 | + |
| 57 | + |
| 58 | +DROP VIEW dd."tables"; |
| 59 | +CREATE VIEW dd."tables" |
| 60 | +AS SELECT n.nspname AS s_name, |
| 61 | + c.relname AS t_name, |
| 62 | + CASE |
| 63 | + WHEN c.relkind = ANY (ARRAY['r'::"char", 'p'::"char"]) THEN 'table'::text |
| 64 | + WHEN c.relkind = 's'::"char" THEN 'special'::text |
| 65 | + WHEN c.relkind = 'f'::"char" THEN 'foreign table'::text |
| 66 | + ELSE NULL::text |
| 67 | + END AS type, |
| 68 | + pg_get_userbyid(c.relowner) AS owner, |
| 69 | + pg_size_pretty(pg_table_size(c.oid::regclass)) AS size_pretty, |
| 70 | + pg_table_size(c.oid::regclass) AS size_bytes, |
| 71 | + c.reltuples AS rows, |
| 72 | + CASE |
| 73 | + WHEN c.reltuples > 0::double precision THEN pg_table_size(c.oid::regclass)::double precision / c.reltuples |
| 74 | + ELSE NULL::double precision |
| 75 | + END AS bytes_per_row, |
| 76 | + pg_size_pretty(pg_total_relation_size(c.oid::regclass)) AS size_plus_indexes, |
| 77 | + obj_description(c.oid, 'pg_class'::name) AS description, |
| 78 | + CASE WHEN n.nspname !~ '^pg_toast'::text AND (n.nspname <> ALL (ARRAY['pg_catalog'::name, 'information_schema'::name])) |
| 79 | + THEN False |
| 80 | + ELSE True |
| 81 | + END AS system_object, |
| 82 | + mt.data_source, |
| 83 | + mt.sensitive |
| 84 | + FROM pg_class c |
| 85 | + LEFT JOIN pg_namespace n ON n.oid = c.relnamespace |
| 86 | + LEFT JOIN dd.meta_table mt ON n.nspname = mt.s_name AND c.relname = mt.t_name |
| 87 | + WHERE (c.relkind = ANY (ARRAY['r'::"char", 'p'::"char", 's'::"char", 'f'::"char"])) |
| 88 | +; |
| 89 | + |
| 90 | + |
| 91 | +-- dd."views" source |
| 92 | +DROP VIEW dd."views"; |
| 93 | +CREATE VIEW dd."views" |
| 94 | +AS SELECT n.nspname AS s_name, |
| 95 | + c.relname AS v_name, |
| 96 | + CASE c.relkind |
| 97 | + WHEN 'v'::"char" THEN 'view'::text |
| 98 | + WHEN 'm'::"char" THEN 'materialized view'::text |
| 99 | + ELSE NULL::text |
| 100 | + END AS view_type, |
| 101 | + pg_get_userbyid(c.relowner) AS owner, |
| 102 | + c.reltuples AS rows, |
| 103 | + pg_size_pretty(pg_table_size(c.oid::regclass)) AS size_pretty, |
| 104 | + pg_table_size(c.oid::regclass) AS size_bytes, |
| 105 | + obj_description(c.oid, 'pg_class'::name) AS description, |
| 106 | + CASE WHEN n.nspname !~ '^pg_toast'::text AND (n.nspname <> ALL (ARRAY['pg_catalog'::name, 'information_schema'::name])) |
| 107 | + THEN False |
| 108 | + ELSE True |
| 109 | + END AS system_object |
| 110 | + FROM pg_class c |
| 111 | + LEFT JOIN pg_namespace n ON n.oid = c.relnamespace |
| 112 | + WHERE (c.relkind = ANY (ARRAY['v'::"char", 'm'::"char"])) AND n.nspname !~ '^pg_toast'::text; |
| 113 | + |
| 114 | + |
| 115 | + |
| 116 | +DROP VIEW dd."columns"; |
| 117 | +CREATE VIEW dd."columns" |
| 118 | +AS SELECT n.nspname AS s_name, |
| 119 | + CASE c.relkind |
| 120 | + WHEN 'r'::"char" THEN 'table'::text |
| 121 | + WHEN 'v'::"char" THEN 'view'::text |
| 122 | + WHEN 'm'::"char" THEN 'materialized view'::text |
| 123 | + WHEN 's'::"char" THEN 'special'::text |
| 124 | + WHEN 'f'::"char" THEN 'foreign table'::text |
| 125 | + WHEN 'p'::"char" THEN 'table'::text |
| 126 | + ELSE NULL::text |
| 127 | + END AS type, |
| 128 | + c.relname AS t_name, |
| 129 | + a.attname AS column_name, |
| 130 | + t.typname AS data_type, |
| 131 | + a.attnum AS "position", |
| 132 | + col_description(c.oid, a.attnum::integer) AS description, |
| 133 | + mc.data_source, |
| 134 | + mc.sensitive, |
| 135 | + CASE WHEN (n.nspname <> ALL (ARRAY['pg_catalog'::name, 'information_schema'::name])) AND n.nspname !~ '^pg_toast'::text |
| 136 | + THEN False |
| 137 | + ELSE True |
| 138 | + END AS system_object |
| 139 | + FROM pg_attribute a |
| 140 | + JOIN pg_class c ON a.attrelid = c.oid |
| 141 | + JOIN pg_namespace n ON n.oid = c.relnamespace |
| 142 | + JOIN pg_type t ON a.atttypid = t.oid |
| 143 | + LEFT JOIN dd.meta_column mc ON n.nspname = mc.s_name AND c.relname = mc.t_name AND a.attname = mc.c_name |
| 144 | + WHERE a.attnum > 0 AND (c.relkind = ANY (ARRAY['r'::"char", 'p'::"char", 's'::"char", 'v'::"char", 'f'::"char", 'm'::"char"])) |
| 145 | +; |
| 146 | + |
| 147 | + |
| 148 | + |
| 149 | +DROP VIEW dd."functions"; |
| 150 | +CREATE VIEW dd."functions" |
| 151 | +AS SELECT n.nspname AS s_name, |
| 152 | + p.proname AS f_name, |
| 153 | + pg_get_function_result(p.oid) AS result_data_types, |
| 154 | + pg_get_function_arguments(p.oid) AS argument_data_types, |
| 155 | + pg_get_userbyid(p.proowner) AS "Owner", |
| 156 | + CASE |
| 157 | + WHEN p.prosecdef THEN 'definer'::text |
| 158 | + ELSE 'invoker'::text |
| 159 | + END AS proc_security, |
| 160 | + array_to_string(p.proacl, ''::text) AS access_privileges, |
| 161 | + l.lanname AS proc_language, |
| 162 | + p.prosrc AS source_code, |
| 163 | + obj_description(p.oid, 'pg_proc'::name) AS description, |
| 164 | + CASE WHEN n.nspname <> ALL (ARRAY['pg_catalog'::name, 'information_schema'::name]) |
| 165 | + THEN False |
| 166 | + ELSE True |
| 167 | + END AS system_object |
| 168 | + FROM pg_proc p |
| 169 | + LEFT JOIN pg_namespace n ON n.oid = p.pronamespace |
| 170 | + LEFT JOIN pg_language l ON l.oid = p.prolang |
| 171 | +; |
| 172 | + |
| 173 | + |
| 174 | +COMMENT ON VIEW dd.schemas IS 'Data dictionary view: Lists schemas'; |
| 175 | +COMMENT ON VIEW dd.tables IS 'Data dictionary view: Lists tables'; |
| 176 | +COMMENT ON VIEW dd.views IS 'Data dictionary view: Lists views and materialized views'; |
| 177 | +COMMENT ON VIEW dd.functions IS 'Data dictionary view: Lists functions (procedures)'; |
| 178 | +COMMENT ON VIEW dd.columns IS 'Data dictionary view: Lists columns in tables'; |
| 179 | + |
| 180 | +COMMENT ON COLUMN dd.schemas.size_plus_indexes IS 'Total size (pretty) of data, TOAST, and indexes. Suitable for display'; |
| 181 | +COMMENT ON COLUMN dd.schemas.size_pretty IS 'Size (pretty) of data and TOAST. Does not include indexes. Suitable for display'; |
| 182 | +COMMENT ON COLUMN dd.schemas.size_bytes IS 'Size (bytes) of data and TOAST. Does not include indexes. Suitable for sorting. '; |
| 183 | + |
| 184 | +COMMENT ON COLUMN dd.tables.size_plus_indexes IS 'Total size (pretty) of data, TOAST, and indexes. Suitable for display'; |
| 185 | +COMMENT ON COLUMN dd.tables.size_pretty IS 'Size (pretty) of data and TOAST. Does not include indexes. Suitable for display'; |
| 186 | +COMMENT ON COLUMN dd.tables.size_bytes IS 'Size (bytes) of data and TOAST. Does not include indexes. Suitable for sorting. '; |
| 187 | + |
| 188 | +COMMENT ON COLUMN dd.schemas.system_object IS 'Allows to easily show/hide system objects.'; |
| 189 | +COMMENT ON COLUMN dd.tables.system_object IS 'Allows to easily show/hide system objects.'; |
| 190 | +COMMENT ON COLUMN dd.views.system_object IS 'Allows to easily show/hide system objects.'; |
| 191 | +COMMENT ON COLUMN dd.functions.system_object IS 'Allows to easily show/hide system objects.'; |
| 192 | +COMMENT ON COLUMN dd.columns.system_object IS 'Allows to easily show/hide system objects.'; |
| 193 | + |
0 commit comments