Merge pull request #67 from CartoDB/faster-quota-check

Optimize CDB_UserDataSize (on behalf of @javisantana) #65
This commit is contained in:
Rafa de la Torre 2015-01-29 18:06:46 +01:00
commit ee8a031ea0
3 changed files with 38 additions and 42 deletions

View File

@ -1,7 +1,7 @@
# cartodb/Makefile # cartodb/Makefile
EXTENSION = cartodb EXTENSION = cartodb
EXTVERSION = 0.5.1 EXTVERSION = 0.5.2
SED = sed SED = sed
@ -30,6 +30,7 @@ UPGRADABLE = \
0.4.0 \ 0.4.0 \
0.4.1 \ 0.4.1 \
0.5.0 \ 0.5.0 \
0.5.1 \
$(EXTVERSION)dev \ $(EXTVERSION)dev \
$(EXTVERSION)next \ $(EXTVERSION)next \
$(END) $(END)

View File

@ -1,3 +1,7 @@
0.5.2 (2015-01-29)
------------------
* Improvement: make CDB_UserDataSize functions much faster.
0.5.1 (2014-11-21) 0.5.1 (2014-11-21)
------------------ ------------------
* Bugfix: Quota check and some organization permissions functions were not properly escaping table name. * Bugfix: Quota check and some organization permissions functions were not properly escaping table name.

View File

@ -3,50 +3,41 @@ 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
-- 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
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() WHERE o_table_schema = schema_name AND o_table_catalog = current_database()
) ),
-- exclude raster "main" tables user_tables AS (
AND table_name NOT IN ( SELECT table_name FROM information_schema.tables
SELECT r_table_name FROM raster_overviews WHERE table_catalog = current_database() AND table_schema = schema_name
WHERE r_table_name = table_name AND table_name != 'spatial_ref_sys'
AND o_table_schema = schema_name AND o_table_catalog = current_database() AND table_name != 'cdb_tablemetadata'
); AND table_type = 'BASE TABLE'
),
table_cat AS (
SELECT
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 -- Division by 2 is for not counting the_geom_webmercator
END AS multiplier FROM table_cat GROUP BY is_overview, is_raster
)
SELECT sum(table_size*multiplier)::int8 INTO total_size FROM sizes;
SELECT COALESCE(INT8(SUM(pg_total_relation_size('"' || schema_name || '"."' || table_name || '"'))), 0) INTO quota_raster IF total_size IS NOT NULL THEN
FROM information_schema.tables RETURN total_size;
WHERE table_catalog = current_database() AND table_schema = schema_name ELSE
AND table_name != 'spatial_ref_sys' RETURN 0;
AND table_name != 'cdb_tablemetadata' END IF;
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;