|
6 | 6 | -- on the referencing side
|
7 | 7 | -- or a bad index
|
8 | 8 |
|
9 |
| -WITH fk_actions ( code, action ) AS ( |
10 |
| - VALUES ( 'a', 'error' ), |
11 |
| - ( 'r', 'restrict' ), |
12 |
| - ( 'c', 'cascade' ), |
13 |
| - ( 'n', 'set null' ), |
14 |
| - ( 'd', 'set default' ) |
15 |
| -), |
16 |
| -fk_list AS ( |
17 |
| - SELECT pg_constraint.oid as fkoid, conrelid, confrelid as parentid, |
18 |
| - conname, relname, nspname, |
19 |
| - fk_actions_update.action as update_action, |
20 |
| - fk_actions_delete.action as delete_action, |
21 |
| - conkey as key_cols |
22 |
| - FROM pg_constraint |
23 |
| - JOIN pg_class ON conrelid = pg_class.oid |
24 |
| - JOIN pg_namespace ON pg_class.relnamespace = pg_namespace.oid |
25 |
| - JOIN fk_actions AS fk_actions_update ON confupdtype = fk_actions_update.code |
26 |
| - JOIN fk_actions AS fk_actions_delete ON confdeltype = fk_actions_delete.code |
27 |
| - WHERE contype = 'f' |
28 |
| -), |
29 |
| -fk_attributes AS ( |
30 |
| - SELECT fkoid, conrelid, attname, attnum |
31 |
| - FROM fk_list |
32 |
| - JOIN pg_attribute |
33 |
| - ON conrelid = attrelid |
34 |
| - AND attnum = ANY( key_cols ) |
35 |
| - ORDER BY fkoid, attnum |
36 |
| -), |
37 |
| -fk_cols_list AS ( |
38 |
| - SELECT fkoid, array_agg(attname) as cols_list |
39 |
| - FROM fk_attributes |
40 |
| - GROUP BY fkoid |
41 |
| -), |
42 |
| -index_list AS ( |
43 |
| - SELECT indexrelid as indexid, |
44 |
| - pg_class.relname as indexname, |
45 |
| - indrelid, |
46 |
| - indkey, |
47 |
| - indpred is not null as has_predicate, |
48 |
| - pg_get_indexdef(indexrelid) as indexdef |
49 |
| - FROM pg_index |
50 |
| - JOIN pg_class ON indexrelid = pg_class.oid |
51 |
| - WHERE indisvalid |
52 |
| -), |
53 |
| -fk_index_match AS ( |
54 |
| - SELECT fk_list.*, |
55 |
| - indexid, |
56 |
| - indexname, |
57 |
| - indkey::int[] as indexatts, |
58 |
| - has_predicate, |
59 |
| - indexdef, |
60 |
| - array_length(key_cols, 1) as fk_colcount, |
61 |
| - array_length(indkey,1) as index_colcount, |
62 |
| - round(pg_relation_size(conrelid)/(1024^2)::numeric) as table_mb, |
63 |
| - cols_list |
64 |
| - FROM fk_list |
65 |
| - JOIN fk_cols_list USING (fkoid) |
66 |
| - LEFT OUTER JOIN index_list |
67 |
| - ON conrelid = indrelid |
68 |
| - AND (indkey::int2[])[0:(array_length(key_cols,1) -1)] @> key_cols |
| 9 | +with fk_actions ( code, action ) as ( |
| 10 | + values ('a', 'error'), |
| 11 | + ('r', 'restrict'), |
| 12 | + ('c', 'cascade'), |
| 13 | + ('n', 'set null'), |
| 14 | + ('d', 'set default') |
| 15 | +), fk_list as ( |
| 16 | + select |
| 17 | + pg_constraint.oid as fkoid, conrelid, confrelid as parentid, |
| 18 | + conname, |
| 19 | + relname, |
| 20 | + nspname, |
| 21 | + fk_actions_update.action as update_action, |
| 22 | + fk_actions_delete.action as delete_action, |
| 23 | + conkey as key_cols |
| 24 | + from pg_constraint |
| 25 | + join pg_class on conrelid = pg_class.oid |
| 26 | + join pg_namespace on pg_class.relnamespace = pg_namespace.oid |
| 27 | + join fk_actions as fk_actions_update on confupdtype = fk_actions_update.code |
| 28 | + join fk_actions as fk_actions_delete on confdeltype = fk_actions_delete.code |
| 29 | + where contype = 'f' |
| 30 | +), fk_attributes as ( |
| 31 | + select fkoid, conrelid, attname, attnum |
| 32 | + from fk_list |
| 33 | + join pg_attribute on conrelid = attrelid and attnum = any(key_cols) |
| 34 | + order by fkoid, attnum |
| 35 | +), fk_cols_list as ( |
| 36 | + select fkoid, array_agg(attname) as cols_list |
| 37 | + from fk_attributes |
| 38 | + group by fkoid |
| 39 | +), index_list as ( |
| 40 | + select |
| 41 | + indexrelid as indexid, |
| 42 | + pg_class.relname as indexname, |
| 43 | + indrelid, |
| 44 | + indkey, |
| 45 | + indpred is not null as has_predicate, |
| 46 | + pg_get_indexdef(indexrelid) as indexdef |
| 47 | + from pg_index |
| 48 | + join pg_class on indexrelid = pg_class.oid |
| 49 | + where indisvalid |
| 50 | +), fk_index_match as ( |
| 51 | + select |
| 52 | + fk_list.*, |
| 53 | + indexid, |
| 54 | + indexname, |
| 55 | + indkey::int[] as indexatts, |
| 56 | + has_predicate, |
| 57 | + indexdef, |
| 58 | + array_length(key_cols, 1) as fk_colcount, |
| 59 | + array_length(indkey,1) as index_colcount, |
| 60 | + round(pg_relation_size(conrelid)/(1024^2)::numeric) as table_mb, |
| 61 | + cols_list |
| 62 | + from fk_list |
| 63 | + join fk_cols_list using (fkoid) |
| 64 | + left join index_list on |
| 65 | + conrelid = indrelid |
| 66 | + and (indkey::int2[])[0:(array_length(key_cols,1) -1)] operator(pg_catalog.@>) key_cols |
69 | 67 |
|
70 |
| -), |
71 |
| -fk_perfect_match AS ( |
72 |
| - SELECT fkoid |
73 |
| - FROM fk_index_match |
74 |
| - WHERE (index_colcount - 1) <= fk_colcount |
75 |
| - AND NOT has_predicate |
76 |
| - AND indexdef LIKE '%USING btree%' |
77 |
| -), |
78 |
| -fk_index_check AS ( |
79 |
| - SELECT 'no index' as issue, *, 1 as issue_sort |
80 |
| - FROM fk_index_match |
81 |
| - WHERE indexid IS NULL |
82 |
| - UNION ALL |
83 |
| - SELECT 'questionable index' as issue, *, 2 |
84 |
| - FROM fk_index_match |
85 |
| - WHERE indexid IS NOT NULL |
86 |
| - AND fkoid NOT IN ( |
87 |
| - SELECT fkoid |
88 |
| - FROM fk_perfect_match) |
89 |
| -), |
90 |
| -parent_table_stats AS ( |
91 |
| - SELECT fkoid, tabstats.relname as parent_name, |
92 |
| - (n_tup_ins + n_tup_upd + n_tup_del + n_tup_hot_upd) as parent_writes, |
93 |
| - round(pg_relation_size(parentid)/(1024^2)::numeric) as parent_mb |
94 |
| - FROM pg_stat_user_tables AS tabstats |
95 |
| - JOIN fk_list |
96 |
| - ON relid = parentid |
97 |
| -), |
98 |
| -fk_table_stats AS ( |
99 |
| - SELECT fkoid, |
100 |
| - (n_tup_ins + n_tup_upd + n_tup_del + n_tup_hot_upd) as writes, |
101 |
| - seq_scan as table_scans |
102 |
| - FROM pg_stat_user_tables AS tabstats |
103 |
| - JOIN fk_list |
104 |
| - ON relid = conrelid |
| 68 | +), fk_perfect_match as ( |
| 69 | + select fkoid |
| 70 | + from fk_index_match |
| 71 | + where |
| 72 | + (index_colcount - 1) <= fk_colcount |
| 73 | + and not has_predicate |
| 74 | + and indexdef like '%USING btree%' |
| 75 | +), fk_index_check as ( |
| 76 | + select 'no index' as issue, *, 1 as issue_sort |
| 77 | + from fk_index_match |
| 78 | + where indexid is null |
| 79 | + union all |
| 80 | + select 'questionable index' as issue, *, 2 |
| 81 | + from fk_index_match |
| 82 | + where |
| 83 | + indexid is not null |
| 84 | + and fkoid not in (select fkoid from fk_perfect_match) |
| 85 | +), parent_table_stats as ( |
| 86 | + select |
| 87 | + fkoid, |
| 88 | + tabstats.relname as parent_name, |
| 89 | + (n_tup_ins + n_tup_upd + n_tup_del + n_tup_hot_upd) as parent_writes, |
| 90 | + round(pg_relation_size(parentid)/(1024^2)::numeric) as parent_mb |
| 91 | + from pg_stat_user_tables as tabstats |
| 92 | + join fk_list on relid = parentid |
| 93 | +), fk_table_stats as ( |
| 94 | + select |
| 95 | + fkoid, |
| 96 | + (n_tup_ins + n_tup_upd + n_tup_del + n_tup_hot_upd) as writes, |
| 97 | + seq_scan as table_scans |
| 98 | + from pg_stat_user_tables as tabstats |
| 99 | + join fk_list on relid = conrelid |
105 | 100 | )
|
106 |
| -SELECT nspname as schema_name, |
107 |
| - relname as table_name, |
108 |
| - conname as fk_name, |
109 |
| - issue, |
110 |
| - table_mb, |
111 |
| - writes, |
112 |
| - table_scans, |
113 |
| - parent_name, |
114 |
| - parent_mb, |
115 |
| - parent_writes, |
116 |
| - cols_list, |
117 |
| - indexdef |
118 |
| -FROM fk_index_check |
119 |
| - JOIN parent_table_stats USING (fkoid) |
120 |
| - JOIN fk_table_stats USING (fkoid) |
121 |
| -WHERE table_mb > 9 |
122 |
| - AND ( writes > 1000 |
123 |
| - OR parent_writes > 1000 |
124 |
| - OR parent_mb > 10 ) |
125 |
| -ORDER BY issue_sort, table_mb DESC, table_name, fk_name; |
126 |
| - |
| 101 | +select |
| 102 | + nspname as schema_name, |
| 103 | + relname as table_name, |
| 104 | + conname as fk_name, |
| 105 | + issue, |
| 106 | + table_mb, |
| 107 | + writes, |
| 108 | + table_scans, |
| 109 | + parent_name, |
| 110 | + parent_mb, |
| 111 | + parent_writes, |
| 112 | + cols_list, |
| 113 | + indexdef |
| 114 | +from fk_index_check |
| 115 | +join parent_table_stats using (fkoid) |
| 116 | +join fk_table_stats using (fkoid) |
| 117 | +where |
| 118 | + table_mb > 9 |
| 119 | + and ( |
| 120 | + writes > 1000 |
| 121 | + or parent_writes > 1000 |
| 122 | + or parent_mb > 10 |
| 123 | + ) |
| 124 | +order by issue_sort, table_mb desc, table_name, fk_name; |
0 commit comments