-
Notifications
You must be signed in to change notification settings - Fork 35
/
Copy pathcalculated_metrics.sql
229 lines (229 loc) · 7.13 KB
/
calculated_metrics.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
with table_summary as (
select count(distinct c.oid) as total_table_count
from pg_class c
join pg_catalog.pg_namespace as ns on (c.relnamespace = ns.oid)
where ns.nspname <> all (array ['pg_catalog', 'information_schema'])
and ns.nspname !~ '^pg_toast'
and c.relkind = ANY (ARRAY ['r', 'p', 't'])
),
foreign_table_summary as (
select count(distinct ft.ftrelid) total_foreign_table_count,
count(
distinct case
when w.fdwname = ANY (ARRAY ['oracle_fdw', 'orafdw','postgres_fdw']) then ft.ftrelid
else null
end
) as supported_foreign_table_count,
count(
distinct case
when w.fdwname != all (ARRAY ['oracle_fdw', 'orafdw','postgres_fdw']) then ft.ftrelid
else null
end
) as unsupported_foreign_table_count
from pg_catalog.pg_foreign_table ft
inner join pg_catalog.pg_class c on c.oid = ft.ftrelid
inner join pg_catalog.pg_foreign_server s on s.oid = ft.ftserver
inner join pg_catalog.pg_foreign_data_wrapper w on s.srvfdw = w.oid
),
extension_summary as (
select count(distinct e.extname) total_extension_count,
count(
distinct case
when e.extname = any (
array ['btree_gin',
'btree_gist',
'chkpass',
'citext',
'cube',
'hstore',
'isn',
'ip4r',
'ltree',
'lo',
'postgresql-hll',
'prefix',
'postgis',
'postgis_raster',
'postgis_sfcgal',
'postgis_tiger_geocoder',
'postgis_topology',
'address_standardizer',
'address_standardizer_data_us',
'plpgsql',
'plv8',
'amcheck',
'auto_explain',
'dblink',
'decoderbufs',
'dict_int',
'earthdistance',
'fuzzystrmatch',
'intagg',
'intarray',
'oracle_fdw',
'orafce',
'pageinspect',
'pgAudit',
'pg_bigm',
'pg_buffercache',
'pg_cron',
'pgcrypto',
'pglogical',
'pgfincore',
'pg_freespacemap',
'pg_hint_plan',
'pgoutput',
'pg_partman',
'pg_prewarm',
'pg_proctab',
'pg_repack',
'pgrowlocks',
'pgstattuple',
'pg_similarity',
'pg_stat_statements',
'pgtap',
'pg_trgm',
'pgtt',
'pgvector',
'pg_visibility',
'pg_wait_sampling',
'plproxy',
'postgres_fdw',
'postgresql_anonymizer',
'rdkit',
'refint',
'sslinfo',
'tablefunc',
'tsm_system_rows',
'tsm_system_time',
'unaccent',
'uuid-ossp']
) then e.extname
else null
end
) as supported_extension_count,
count(
distinct case
when e.extname != all (
array ['btree_gin',
'btree_gist',
'chkpass',
'citext',
'cube',
'hstore',
'isn',
'ip4r',
'ltree',
'lo',
'postgresql-hll',
'prefix',
'postgis',
'postgis_raster',
'postgis_sfcgal',
'postgis_tiger_geocoder',
'postgis_topology',
'address_standardizer',
'address_standardizer_data_us',
'plpgsql',
'plv8',
'amcheck',
'auto_explain',
'dblink',
'decoderbufs',
'dict_int',
'earthdistance',
'fuzzystrmatch',
'intagg',
'intarray',
'oracle_fdw',
'orafce',
'pageinspect',
'pgAudit',
'pg_bigm',
'pg_buffercache',
'pg_cron',
'pgcrypto',
'pglogical',
'pgfincore',
'pg_freespacemap',
'pg_hint_plan',
'pgoutput',
'pg_partman',
'pg_prewarm',
'pg_proctab',
'pg_repack',
'pgrowlocks',
'pgstattuple',
'pg_similarity',
'pg_stat_statements',
'pgtap',
'pg_trgm',
'pgtt',
'pgvector',
'pg_visibility',
'pg_wait_sampling',
'plproxy',
'postgres_fdw',
'postgresql_anonymizer',
'rdkit',
'refint',
'sslinfo',
'tablefunc',
'tsm_system_rows',
'tsm_system_time',
'unaccent',
'uuid-ossp']
) then e.extname
else null
end
) as unsupported_extension_count
from pg_extension e
),
calculated_metrics as (
select 'VERSION_NUM' as metric_name,
current_setting('server_version_num') as metric_value
union
select 'VERSION' as metric_name,
current_setting('server_version') as metric_value
union
select 'UNSUPPORTED_EXTENSION_COUNT' as metric_name,
cast(es.unsupported_extension_count as varchar) as metric_value
from extension_summary es
union
select 'SUPPORTED_EXTENSION_COUNT' as metric_name,
cast(es.supported_extension_count as varchar) as metric_value
from extension_summary es
union all
select 'EXTENSION_COUNT' as metric_name,
cast(es.total_extension_count as varchar) as metric_value
from extension_summary es
union all
select 'FOREIGN_TABLE_COUNT' as metric_name,
cast(fts.total_foreign_table_count as varchar) as metric_value
from foreign_table_summary fts
union all
select 'UNSUPPORTED_FOREIGN_TABLE_COUNT' as metric_name,
cast(fts.unsupported_foreign_table_count as varchar) as metric_value
from foreign_table_summary fts
union all
select 'SUPPORTED_FOREIGN_TABLE_COUNT' as metric_name,
cast(fts.supported_foreign_table_count as varchar) as metric_value
from foreign_table_summary fts
union all
select 'TABLE_COUNT' as metric_name,
cast(ts.total_table_count as varchar) as metric_value
from table_summary ts
),
src as (
select 'CALCULATED_METRIC' as metric_category,
metric_name,
metric_value
from calculated_metrics
)
select chr(34) || :PKEY || chr(34) as pkey,
chr(34) || :DMA_SOURCE_ID || chr(34) as dma_source_id,
chr(34) || :DMA_MANUAL_ID || chr(34) as dma_manual_id,
chr(34) || src.metric_category || chr(34) as metric_category,
chr(34) || src.metric_name || chr(34) as metric_name,
chr(34) || src.metric_value || chr(34) as metric_value
from src;