Optimize CDB_UserDataSize (on behalf of @javisantana) #65
This commit is contained in:
parent
dbb6f42b99
commit
bf622ae5a6
@ -3,50 +3,37 @@ CREATE OR REPLACE FUNCTION CDB_UserDataSize(schema_name TEXT)
|
|||||||
RETURNS bigint AS
|
RETURNS bigint AS
|
||||||
$$
|
$$
|
||||||
DECLARE
|
DECLARE
|
||||||
quota_vector INT8;
|
total_size INT8;
|
||||||
quota_raster INT8;
|
|
||||||
BEGIN
|
BEGIN
|
||||||
-- TODO: double check queries. Maybe use CDB_TableMetadata for lookup?
|
WITH raster_tables AS (
|
||||||
-- Also, "table_name" sounds sensible to search_path
|
SELECT o_table_name, r_table_name FROM raster_overviews
|
||||||
|
WHERE o_table_schema = schema_name AND o_table_catalog = current_database()
|
||||||
-- Division by 2 is for not counting the_geom_webmercator
|
),
|
||||||
SELECT COALESCE(INT8(SUM(pg_total_relation_size('"' || schema_name || '"."' || table_name || '"')) / 2), 0) INTO quota_vector
|
user_tables AS (
|
||||||
FROM information_schema.tables
|
SELECT table_name FROM information_schema.tables
|
||||||
WHERE table_catalog = current_database() AND table_schema = schema_name
|
WHERE table_catalog = current_database() AND table_schema = schema_name
|
||||||
AND table_name != 'spatial_ref_sys'
|
AND table_name != 'spatial_ref_sys'
|
||||||
AND table_name != 'cdb_tablemetadata'
|
AND table_name != 'cdb_tablemetadata'
|
||||||
AND table_type = 'BASE TABLE'
|
AND table_type = 'BASE TABLE'
|
||||||
-- exclude raster overview tables
|
),
|
||||||
AND table_name NOT IN (
|
table_cat AS (
|
||||||
SELECT o_table_name FROM raster_overviews
|
SELECT
|
||||||
WHERE o_table_schema = schema_name AND o_table_catalog = current_database()
|
table_name,
|
||||||
|
EXISTS(select * from raster_tables where o_table_name = table_name) AS is_overview,
|
||||||
|
EXISTS(SELECT * FROM raster_tables WHERE r_table_name = table_name) AS is_raster
|
||||||
|
FROM user_tables
|
||||||
|
),
|
||||||
|
sizes AS (
|
||||||
|
SELECT COALESCE(INT8(SUM(pg_total_relation_size('"' || schema_name || '"."' || table_name || '"')))) table_size,
|
||||||
|
CASE
|
||||||
|
WHEN is_overview THEN 0
|
||||||
|
WHEN is_raster THEN 1
|
||||||
|
ELSE 0.5
|
||||||
|
END AS multiplier FROM table_cat GROUP BY is_overview, is_raster
|
||||||
)
|
)
|
||||||
-- exclude raster "main" tables
|
SELECT sum(table_size*multiplier)::int8 INTO total_size FROM sizes;
|
||||||
AND table_name NOT IN (
|
|
||||||
SELECT r_table_name FROM raster_overviews
|
|
||||||
WHERE r_table_name = table_name
|
|
||||||
AND o_table_schema = schema_name AND o_table_catalog = current_database()
|
|
||||||
);
|
|
||||||
|
|
||||||
SELECT COALESCE(INT8(SUM(pg_total_relation_size('"' || schema_name || '"."' || table_name || '"'))), 0) INTO quota_raster
|
RETURN total_size;
|
||||||
FROM information_schema.tables
|
|
||||||
WHERE table_catalog = current_database() AND table_schema = schema_name
|
|
||||||
AND table_name != 'spatial_ref_sys'
|
|
||||||
AND table_name != 'cdb_tablemetadata'
|
|
||||||
AND table_type = 'BASE TABLE'
|
|
||||||
-- exclude raster overview tables
|
|
||||||
AND table_name NOT IN (
|
|
||||||
SELECT o_table_name FROM raster_overviews
|
|
||||||
WHERE o_table_schema = schema_name AND o_table_catalog = current_database()
|
|
||||||
)
|
|
||||||
-- filter to raster "main" tables
|
|
||||||
AND table_name IN (
|
|
||||||
SELECT r_table_name FROM raster_overviews
|
|
||||||
WHERE r_table_name = table_name
|
|
||||||
AND o_table_schema = schema_name AND o_table_catalog = current_database()
|
|
||||||
);
|
|
||||||
|
|
||||||
RETURN quota_vector + quota_raster;
|
|
||||||
END;
|
END;
|
||||||
$$
|
$$
|
||||||
LANGUAGE 'plpgsql' VOLATILE;
|
LANGUAGE 'plpgsql' VOLATILE;
|
||||||
|
Loading…
Reference in New Issue
Block a user