forked from timescale/timescaledb
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathsize_utils.sql
418 lines (388 loc) · 14.9 KB
/
size_utils.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
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
-- This file contains utility functions to get the relation size
-- of hypertables, chunks, and indexes on hypertables.
-- Get relation size of hypertable
-- like pg_relation_size(hypertable)
-- (https://www.postgresql.org/docs/9.6/static/functions-admin.html#FUNCTIONS-ADMIN-DBSIZE)
--
-- main_table - hypertable to get size of
--
-- Returns:
-- table_bytes - Disk space used by main_table (like pg_relation_size(main_table))
-- index_bytes - Disc space used by indexes
-- toast_bytes - Disc space of toast tables
-- total_bytes - Total disk space used by the specified table, including all indexes and TOAST data
CREATE OR REPLACE FUNCTION hypertable_relation_size(
main_table REGCLASS
)
RETURNS TABLE (table_bytes BIGINT,
index_bytes BIGINT,
toast_bytes BIGINT,
total_bytes BIGINT
) LANGUAGE PLPGSQL STABLE
AS
$BODY$
DECLARE
table_name NAME;
schema_name NAME;
BEGIN
SELECT relname, nspname
INTO STRICT table_name, schema_name
FROM pg_class c
INNER JOIN pg_namespace n ON (n.OID = c.relnamespace)
WHERE c.OID = main_table;
RETURN QUERY EXECUTE format(
$$
SELECT table_bytes,
index_bytes,
toast_bytes,
total_bytes
FROM (
SELECT *, total_bytes-index_bytes-COALESCE(toast_bytes,0) AS table_bytes FROM (
SELECT
sum(pg_total_relation_size('"' || c.schema_name || '"."' || c.table_name || '"'))::bigint as total_bytes,
sum(pg_indexes_size('"' || c.schema_name || '"."' || c.table_name || '"'))::bigint AS index_bytes,
sum(pg_total_relation_size(reltoastrelid))::bigint AS toast_bytes
FROM
_timescaledb_catalog.hypertable h,
_timescaledb_catalog.chunk c,
pg_class pgc,
pg_namespace pns
WHERE h.schema_name = %L
AND h.table_name = %L
AND c.hypertable_id = h.id
AND pgc.relname = h.table_name
AND pns.oid = pgc.relnamespace
AND pns.nspname = h.schema_name
AND relkind = 'r'
) sub1
) sub2;
$$,
schema_name, table_name);
END;
$BODY$;
CREATE OR REPLACE FUNCTION _timescaledb_internal.range_value_to_pretty(
time_value BIGINT,
column_type REGTYPE
)
RETURNS TEXT LANGUAGE PLPGSQL STABLE AS
$BODY$
DECLARE
BEGIN
IF NOT _timescaledb_internal.dimension_is_finite(time_value) THEN
RETURN '';
END IF;
IF time_value IS NULL THEN
RETURN format('%L', NULL);
END IF;
CASE column_type
WHEN 'BIGINT'::regtype, 'INTEGER'::regtype, 'SMALLINT'::regtype THEN
RETURN format('%L', time_value); -- scale determined by user.
WHEN 'TIMESTAMP'::regtype, 'TIMESTAMPTZ'::regtype THEN
-- assume time_value is in microsec
RETURN format('%1$L', _timescaledb_internal.to_timestamp(time_value)); -- microseconds
WHEN 'DATE'::regtype THEN
RETURN format('%L', timezone('UTC',_timescaledb_internal.to_timestamp(time_value))::date);
ELSE
RETURN time_value;
END CASE;
END
$BODY$;
CREATE OR REPLACE FUNCTION _timescaledb_internal.partitioning_column_to_pretty(
d _timescaledb_catalog.dimension
)
RETURNS TEXT LANGUAGE PLPGSQL STABLE AS
$BODY$
DECLARE
BEGIN
IF d.partitioning_func IS NULL THEN
RETURN d.column_name;
ELSE
RETURN d.partitioning_func_schema || '.' || d.partitioning_func
|| '(' || d.column_name || ')';
END IF;
END
$BODY$;
-- Get relation size of hypertable
-- like pg_relation_size(hypertable)
-- (https://www.postgresql.org/docs/9.6/static/functions-admin.html#FUNCTIONS-ADMIN-DBSIZE)
--
-- main_table - hypertable to get size of
--
-- Returns:
-- table_size - Pretty output of table_bytes
-- index_bytes - Pretty output of index_bytes
-- toast_bytes - Pretty output of toast_bytes
-- total_size - Pretty output of total_bytes
CREATE OR REPLACE FUNCTION hypertable_relation_size_pretty(
main_table REGCLASS
)
RETURNS TABLE (table_size TEXT,
index_size TEXT,
toast_size TEXT,
total_size TEXT) LANGUAGE PLPGSQL STABLE
AS
$BODY$
DECLARE
table_name NAME;
schema_name NAME;
BEGIN
RETURN QUERY
SELECT pg_size_pretty(table_bytes) as table,
pg_size_pretty(index_bytes) as index,
pg_size_pretty(toast_bytes) as toast,
pg_size_pretty(total_bytes) as total
FROM hypertable_relation_size(main_table);
END;
$BODY$;
-- Get relation size of the chunks of an hypertable
-- like pg_relation_size
-- (https://www.postgresql.org/docs/9.6/static/functions-admin.html#FUNCTIONS-ADMIN-DBSIZE)
--
-- main_table - hypertable to get size of
--
-- Returns:
-- chunk_id - Timescaledb id of a chunk
-- chunk_table - Table used for the chunk
-- partitioning_columns - Partitioning column names
-- partitioning_column_types - Type of partitioning columns
-- partitioning_hash_functions - Hash functions of partitioning columns
-- ranges - Partition ranges for each dimension of the chunk
-- table_bytes - Disk space used by main_table
-- index_bytes - Disk space used by indexes
-- toast_bytes - Disc space of toast tables
-- total_bytes - Disk space used in total
CREATE OR REPLACE FUNCTION chunk_relation_size(
main_table REGCLASS
)
RETURNS TABLE (chunk_id INT,
chunk_table TEXT,
partitioning_columns NAME[],
partitioning_column_types REGTYPE[],
partitioning_hash_functions TEXT[],
ranges int8range[],
table_bytes BIGINT,
index_bytes BIGINT,
toast_bytes BIGINT,
total_bytes BIGINT)
LANGUAGE PLPGSQL STABLE
AS
$BODY$
DECLARE
table_name NAME;
schema_name NAME;
BEGIN
SELECT relname, nspname
INTO STRICT table_name, schema_name
FROM pg_class c
INNER JOIN pg_namespace n ON (n.OID = c.relnamespace)
WHERE c.OID = main_table;
RETURN QUERY EXECUTE format(
$$
SELECT chunk_id,
chunk_table,
partitioning_columns,
partitioning_column_types,
partitioning_hash_functions,
ranges,
table_bytes,
index_bytes,
toast_bytes,
total_bytes
FROM (
SELECT *,
total_bytes-index_bytes-COALESCE(toast_bytes,0) AS table_bytes
FROM (
SELECT c.id as chunk_id,
'"' || c.schema_name || '"."' || c.table_name || '"' as chunk_table,
pg_total_relation_size('"' || c.schema_name || '"."' || c.table_name || '"') AS total_bytes,
pg_indexes_size('"' || c.schema_name || '"."' || c.table_name || '"') AS index_bytes,
pg_total_relation_size(reltoastrelid) AS toast_bytes,
array_agg(d.column_name ORDER BY d.interval_length, d.column_name ASC) as partitioning_columns,
array_agg(d.column_type ORDER BY d.interval_length, d.column_name ASC) as partitioning_column_types,
array_agg(d.partitioning_func_schema || '.' || d.partitioning_func ORDER BY d.interval_length, d.column_name ASC) as partitioning_hash_functions,
array_agg(int8range(range_start, range_end) ORDER BY d.interval_length, d.column_name ASC) as ranges
FROM
_timescaledb_catalog.hypertable h,
_timescaledb_catalog.chunk c,
_timescaledb_catalog.chunk_constraint cc,
_timescaledb_catalog.dimension d,
_timescaledb_catalog.dimension_slice ds,
pg_class pgc,
pg_namespace pns
WHERE h.schema_name = %L
AND h.table_name = %L
AND pgc.relname = h.table_name
AND pns.oid = pgc.relnamespace
AND pns.nspname = h.schema_name
AND relkind = 'r'
AND c.hypertable_id = h.id
AND c.id = cc.chunk_id
AND cc.dimension_slice_id = ds.id
AND ds.dimension_id = d.id
GROUP BY c.id, pgc.reltoastrelid, pgc.oid ORDER BY c.id
) sub1
) sub2;
$$,
schema_name, table_name);
END;
$BODY$;
-- Get relation size of the chunks of an hypertable
-- like pg_relation_size
-- (https://www.postgresql.org/docs/9.6/static/functions-admin.html#FUNCTIONS-ADMIN-DBSIZE)
--
-- main_table - hypertable to get size of
--
-- Returns:
-- chunk_id - Timescaledb id of a chunk
-- chunk_table - Table used for the chunk
-- partitioning_columns - Partitioning column names
-- partitioning_column_types - Type of partitioning columns
-- partitioning_hash_functions - Hash functions of partitioning columns
-- ranges - Partition ranges for each dimension of the chunk
-- table_size - Pretty output of table_bytes
-- index_size - Pretty output of index_bytes
-- toast_size - Pretty output of toast_bytes
-- total_size - Pretty output of total_bytes
CREATE OR REPLACE FUNCTION chunk_relation_size_pretty(
main_table REGCLASS
)
RETURNS TABLE (chunk_id INT,
chunk_table TEXT,
partitioning_columns NAME[],
partitioning_column_types REGTYPE[],
partitioning_hash_functions TEXT[],
ranges TEXT[],
table_size TEXT,
index_size TEXT,
toast_size TEXT,
total_size TEXT
)
LANGUAGE PLPGSQL STABLE
AS
$BODY$
DECLARE
table_name NAME;
schema_name NAME;
BEGIN
SELECT relname, nspname
INTO STRICT table_name, schema_name
FROM pg_class c
INNER JOIN pg_namespace n ON (n.OID = c.relnamespace)
WHERE c.OID = main_table;
RETURN QUERY EXECUTE format(
$$
SELECT chunk_id,
chunk_table,
partitioning_columns,
partitioning_column_types,
partitioning_functions,
ranges,
pg_size_pretty(table_bytes) AS table,
pg_size_pretty(index_bytes) AS index,
pg_size_pretty(toast_bytes) AS toast,
pg_size_pretty(total_bytes) AS total
FROM (
SELECT *,
total_bytes-index_bytes-COALESCE(toast_bytes,0) AS table_bytes
FROM (
SELECT c.id as chunk_id,
'"' || c.schema_name || '"."' || c.table_name || '"' as chunk_table,
pg_total_relation_size('"' || c.schema_name || '"."' || c.table_name || '"') AS total_bytes,
pg_indexes_size('"' || c.schema_name || '"."' || c.table_name || '"') AS index_bytes,
pg_total_relation_size(reltoastrelid) AS toast_bytes,
array_agg(d.column_name ORDER BY d.interval_length, d.column_name ASC) as partitioning_columns,
array_agg(d.column_type ORDER BY d.interval_length, d.column_name ASC) as partitioning_column_types,
array_agg(d.partitioning_func_schema || '.' || d.partitioning_func ORDER BY d.interval_length, d.column_name ASC) as partitioning_functions,
array_agg('[' || _timescaledb_internal.range_value_to_pretty(range_start, column_type) ||
',' ||
_timescaledb_internal.range_value_to_pretty(range_end, column_type) || ')' ORDER BY d.interval_length, d.column_name ASC) as ranges
FROM
_timescaledb_catalog.hypertable h,
_timescaledb_catalog.chunk c,
_timescaledb_catalog.chunk_constraint cc,
_timescaledb_catalog.dimension d,
_timescaledb_catalog.dimension_slice ds,
pg_class pgc,
pg_namespace pns
WHERE h.schema_name = %L
AND h.table_name = %L
AND pgc.relname = h.table_name
AND pns.oid = pgc.relnamespace
AND pns.nspname = h.schema_name
AND relkind = 'r'
AND c.hypertable_id = h.id
AND c.id = cc.chunk_id
AND cc.dimension_slice_id = ds.id
AND ds.dimension_id = d.id
GROUP BY c.id, pgc.reltoastrelid, pgc.oid ORDER BY c.id
) sub1
) sub2;
$$,
schema_name, table_name);
END;
$BODY$;
-- Get sizes of indexes on a hypertable
--
-- main_table - hypertable to get index sizes of
--
-- Returns:
-- index_name - index on hyper table
-- total_bytes - size of index on disk
CREATE OR REPLACE FUNCTION indexes_relation_size(
main_table REGCLASS
)
RETURNS TABLE (index_name TEXT,
total_bytes BIGINT)
LANGUAGE PLPGSQL STABLE
AS
$BODY$
<<main>>
DECLARE
table_name NAME;
schema_name NAME;
BEGIN
SELECT relname, nspname
INTO STRICT table_name, schema_name
FROM pg_class c
INNER JOIN pg_namespace n ON (n.OID = c.relnamespace)
WHERE c.OID = main_table;
RETURN QUERY
SELECT h.schema_name || '.' || ci.hypertable_index_name,
sum(pg_relation_size(c.oid))::bigint
FROM
pg_class c,
pg_namespace n,
_timescaledb_catalog.hypertable h,
_timescaledb_catalog.chunk ch,
_timescaledb_catalog.chunk_index ci
WHERE ch.schema_name = n.nspname
AND c.relnamespace = n.oid
AND c.relname = ci.index_name
AND ch.id = ci.chunk_id
AND h.id = ci.hypertable_id
AND h.schema_name = main.schema_name
AND h.table_name = main.table_name
GROUP BY h.schema_name, ci.hypertable_index_name;
END;
$BODY$;
-- Get sizes of indexes on a hypertable
--
-- main_table - hypertable to get index sizes of
--
-- Returns:
-- index_name - index on hyper table
-- total_size - pretty output of total_bytes
CREATE OR REPLACE FUNCTION indexes_relation_size_pretty(
main_table REGCLASS
)
RETURNS TABLE (index_name TEXT,
total_size TEXT) LANGUAGE PLPGSQL STABLE
AS
$BODY$
BEGIN
RETURN QUERY
SELECT s.index_name,
pg_size_pretty(s.total_bytes)
FROM indexes_relation_size(main_table) s;
END;
$BODY$;