From 3b5c1f65cb5851df8e15caf0f5ba94d9b972d80d Mon Sep 17 00:00:00 2001 From: Kartones Date: Tue, 18 Nov 2014 15:24:54 +0100 Subject: [PATCH] #1138 Quota changes, raster import cartodbfication and quota spec --- Makefile | 8 +- NEWS.md | 10 + scripts-available/CDB_CartodbfyTable.sql | 99 +++++++- scripts-available/CDB_Quota.sql | 60 +++-- test/CDB_CartodbfyTableTest_expect | 2 +- test/extension/run_at_cartodb_schema.sql | 2 + test/extension/test.sh | 284 +++++++++++++++++++++++ 7 files changed, 436 insertions(+), 29 deletions(-) create mode 100644 test/extension/run_at_cartodb_schema.sql create mode 100644 test/extension/test.sh diff --git a/Makefile b/Makefile index a6f3845..a4c8d9c 100644 --- a/Makefile +++ b/Makefile @@ -1,7 +1,7 @@ # cartodb/Makefile EXTENSION = cartodb -EXTVERSION = 0.4.1 +EXTVERSION = 0.5.0 SED = sed @@ -28,6 +28,7 @@ UPGRADABLE = \ 0.3.5 \ 0.3.6 \ 0.4.0 \ + 0.4.1 \ $(EXTVERSION)dev \ $(EXTVERSION)next \ $(END) @@ -102,7 +103,10 @@ legacy_regress: $(REGRESS_OLD) Makefile test_organization: bash test/organization/test.sh +test_extension_new: + bash test/extension/test.sh + legacy_tests: legacy_regress -installcheck: legacy_tests test_organization +installcheck: legacy_tests test_extension_new test_organization diff --git a/NEWS.md b/NEWS.md index 15955a6..68efc2b 100644 --- a/NEWS.md +++ b/NEWS.md @@ -1,3 +1,13 @@ +0.5.0 (2014-09-21) +------------------ +* Support of raster tables for cartodbfication +* Modified quota functions: vector tables stay the same, raster tables count as full size (as have no + the_geom + the_geom_webmercator combo) and raster overviews are not counted + +0.4.1 (2014-09-21) +------------------ +* Bugfix for Cartodbfication: Set primary key of the table if not already present (e.g. tables created from SQL API) + 0.4.0 (2014-08-27) ------------------ Added CDB_Math_Mode function diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 8e9654a..6c92c52 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -3,8 +3,7 @@ -- * CDB_TableMetadata.sql -- * CDB_Quota.sql -- * _CDB_UserQuotaInBytes() function, installed by rails --- (user.rebuild_quota_trigger, called by rake task --- cartodb:db:update_test_quota_trigger) +-- (user.rebuild_quota_trigger, called by rake task cartodb:db:update_test_quota_trigger) -- 1) Required checks before running cartodbfication -- Either will pass silenty or raise an exception @@ -22,7 +21,7 @@ BEGIN BEGIN EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name::text) INTO sql; EXCEPTION WHEN undefined_function THEN - RAISE EXCEPTION 'Please set user quota before cartodbfying tables.'; + RAISE EXCEPTION 'Please set user quota before cartodbfying tables.'; END; END; $$ LANGUAGE PLPGSQL; @@ -466,7 +465,7 @@ END; $$ LANGUAGE PLPGSQL; --- 8) Create all triggers +-- 8.a) Create all triggers -- NOTE: drop/create has the side-effect of re-enabling disabled triggers CREATE OR REPLACE FUNCTION _CDB_create_triggers(schema_name TEXT, reloid REGCLASS) RETURNS void @@ -512,6 +511,46 @@ BEGIN END; $$ LANGUAGE PLPGSQL; +-- 8.b) Create all raster triggers +-- NOTE: drop/create has the side-effect of re-enabling disabled triggers +CREATE OR REPLACE FUNCTION _CDB_create_raster_triggers(schema_name TEXT, reloid REGCLASS) + RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN +-- "track_updates" + sql := 'CREATE trigger track_updates AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE ON ' + || reloid::text + || ' FOR EACH STATEMENT EXECUTE PROCEDURE public.cdb_tablemetadata_trigger()'; + EXECUTE sql; + +-- "update_updated_at" +-- TODO: why _before_ and not after ? + sql := 'CREATE trigger update_updated_at_trigger BEFORE UPDATE ON ' + || reloid::text + || ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_updated_at()'; + EXECUTE sql; + +-- "test_quota" and "test_quota_per_row" + + sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON ' + || reloid::text + || ' EXECUTE PROCEDURE public.CDB_CheckQuota(1, ''-1'', ''' + || schema_name::text + || ''')'; + EXECUTE sql; + + sql := 'CREATE TRIGGER test_quota_per_row BEFORE UPDATE OR INSERT ON ' + || reloid::text + || ' FOR EACH ROW EXECUTE PROCEDURE public.CDB_CheckQuota(0.001, ''-1'', ''' + || schema_name::text + || ''')'; + EXECUTE sql; +END; +$$ LANGUAGE PLPGSQL; + + -- Update the_geom_webmercator CREATE OR REPLACE FUNCTION _CDB_update_the_geom_webmercator() @@ -532,15 +571,47 @@ END; $$ LANGUAGE plpgsql VOLATILE; +-- Auxiliary function +CREATE OR REPLACE FUNCTION _CDB_is_raster_table(schema_name TEXT, reloid REGCLASS) + RETURNS BOOLEAN +AS $$ +DECLARE + sql TEXT; + is_raster BOOLEAN; +BEGIN + IF cartodb.schema_exists(schema_name) = FALSE THEN + RAISE EXCEPTION 'Invalid schema name "%"', schema_name; + END IF; + + BEGIN + sql := 'SELECT the_raster_webmercator FROM ' + || quote_ident(schema_name::TEXT) + || '.' + || quote_ident(reloid::TEXT) + || ' LIMIT 1'; + is_raster = TRUE; + EXECUTE sql; + + EXCEPTION WHEN undefined_column THEN + is_raster = FALSE; + END; + + RETURN is_raster; +END; +$$ LANGUAGE PLPGSQL; + + + -- //////////////////////////////////////////////////// --- Ensure a table is a "cartodb" table --- See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table +-- Ensure a table is a "cartodb" table (See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table) +-- Rails code replicates this call at User.cartodbfy() CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(schema_name TEXT, reloid REGCLASS) RETURNS void AS $$ DECLARE exists_geom_cols BOOLEAN[]; + is_raster BOOLEAN; BEGIN PERFORM cartodb._CDB_check_prerequisites(schema_name, reloid); @@ -550,13 +621,19 @@ BEGIN -- Ensure required fields exist PERFORM cartodb._CDB_create_cartodb_id_column(reloid); PERFORM cartodb._CDB_create_timestamp_columns(reloid); - SELECT cartodb._CDB_create_the_geom_columns(reloid) INTO exists_geom_cols; - -- Both only populate if proceeds - PERFORM cartodb._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols); - PERFORM cartodb._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols); + SELECT cartodb._CDB_is_raster_table(schema_name, reloid) INTO is_raster; + IF is_raster THEN + PERFORM cartodb._CDB_create_raster_triggers(schema_name, reloid); + ELSE + SELECT cartodb._CDB_create_the_geom_columns(reloid) INTO exists_geom_cols; - PERFORM cartodb._CDB_create_triggers(schema_name, reloid); + -- Both only populate if proceeds + PERFORM cartodb._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols); + PERFORM cartodb._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols); + + PERFORM cartodb._CDB_create_triggers(schema_name, reloid); + END IF; END; $$ LANGUAGE PLPGSQL; diff --git a/scripts-available/CDB_Quota.sql b/scripts-available/CDB_Quota.sql index 235bdc9..e52c97f 100644 --- a/scripts-available/CDB_Quota.sql +++ b/scripts-available/CDB_Quota.sql @@ -2,24 +2,54 @@ CREATE OR REPLACE FUNCTION CDB_UserDataSize(schema_name TEXT) RETURNS bigint AS $$ - -- TODO: double check this query. Maybe use CDB_TableMetadata for lookup ? - -- also, it's "table_name" sounds sensible to search_path - -- - -- NOTE: division by 2 is an hack for the_geom_webmercator - -- - SELECT coalesce(int8(sum(pg_total_relation_size(schema_name || '.' || table_name)) / 2), 0) - AS quota +DECLARE + quota_vector INT8; + quota_raster INT8; +BEGIN + -- TODO: double check queries. Maybe use CDB_TableMetadata for lookup? + -- Also, "table_name" sounds sensible to search_path + + -- 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' - AND table_name NOT IN ( - SELECT o_table_name FROM raster_overviews - WHERE o_table_schema = schema_name AND o_table_catalog = current_database() - ); + 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() + ) + -- exclude raster "main" tables + 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 + 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; $$ -LANGUAGE 'sql' VOLATILE; +LANGUAGE 'plpgsql' VOLATILE; -- Return the estimated size of user data. Used for quota checking. diff --git a/test/CDB_CartodbfyTableTest_expect b/test/CDB_CartodbfyTableTest_expect index 588102b..5a3b090 100644 --- a/test/CDB_CartodbfyTableTest_expect +++ b/test/CDB_CartodbfyTableTest_expect @@ -3,7 +3,7 @@ CREATE FUNCTION SELECT 1 ERROR: Please set user quota before cartodbfying tables. CONTEXT: SQL statement "SELECT cartodb._CDB_check_prerequisites(schema_name, reloid)" -PL/pgSQL function cdb_cartodbfytable(text,regclass) line 6 at PERFORM +PL/pgSQL function cdb_cartodbfytable(text,regclass) line 7 at PERFORM 0 single non-geometrical column cartodbfied fine DROP TABLE diff --git a/test/extension/run_at_cartodb_schema.sql b/test/extension/run_at_cartodb_schema.sql new file mode 100644 index 0000000..980c7a7 --- /dev/null +++ b/test/extension/run_at_cartodb_schema.sql @@ -0,0 +1,2 @@ +SET SCHEMA 'cartodb'; +\i scripts-available/CDB_Quota.sql \ No newline at end of file diff --git a/test/extension/test.sh b/test/extension/test.sh new file mode 100644 index 0000000..4f3a469 --- /dev/null +++ b/test/extension/test.sh @@ -0,0 +1,284 @@ +#!/bin/sh + +# +# Tests for the extension since version 0.5.0. They don't replace SQL based ones, for now need to run both +# + +# It is expected that you run this script as a PostgreSQL superuser, for example: +# +# PGUSER=postgres bash ./test.sh +# + +DATABASE=test_extension +CMD='echo psql' +CMD=psql + +OK=0 +PARTIALOK=0 + +function set_failed() { + OK=1 + PARTIALOK=1 +} + + +function clear_partial_result() { + PARTIALOK=0 +} + + +function sql() { + local ROLE + local QUERY + if [[ $# -ge 2 ]] + then + ROLE="$1" + QUERY="$2" + else + QUERY="$1" + fi + + if [ -n "${ROLE}" ]; then + log_debug "Executing query '${QUERY}' as ${ROLE}" + RESULT=`${CMD} -U "${ROLE}" ${DATABASE} -c "${QUERY}" -A -t` + else + log_debug "Executing query '${QUERY}'" + RESULT=`${CMD} ${DATABASE} -c "${QUERY}" -A -t` + fi + CODERESULT=$? + + echo ${RESULT} + echo + + if [[ ${CODERESULT} -ne 0 ]] + then + echo -n "FAILED TO EXECUTE QUERY: " + log_warning "${QUERY}" + if [[ "$3" != "fails" ]] + then + log_error "${QUERY}" + set_failed + fi + else + if [[ "$3" == "fails" ]] + then + log_error "QUERY: '${QUERY}' was expected to fail and it did not fail" + set_failed + fi + fi + + if [[ "$3" == "should" ]] + then + if [[ "${RESULT}" != "$4" ]] + then + log_error "QUERY '${QUERY}' expected result '${4}' but got '${RESULT}'" + set_failed + fi + fi +} + + +function log_info() +{ + echo + echo + echo + _log "1;34m" "$1" +} + +function log_error() { + _log "1;31m" "$1" +} + +function log_debug() { + _log "1;32m" "> $1" +} + +function log_warning() { + _log "0;33m" "$1" +} + +function _log() { + echo -e "\033[$1$2\033[0m" +} + +# '############################ HELPERS #############################' +function create_role_and_schema() { + local ROLE=$1 + sql "CREATE ROLE ${ROLE} LOGIN;" + sql "GRANT CONNECT ON DATABASE \"${DATABASE}\" TO ${ROLE};" + sql "CREATE SCHEMA ${ROLE} AUTHORIZATION ${ROLE};" + sql "SELECT cartodb.CDB_Organization_Create_Member('${ROLE}');" +} + + +function drop_role_and_schema() { + local ROLE=$1 + sql "DROP SCHEMA \"${ROLE}\";" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM \"${ROLE}\";" + sql "DROP ROLE \"${ROLE}\";" +} + + +function create_table() { + if [[ $# -ne 2 ]] + then + log_error "create_table requires two arguments: role and table_name" + exit 1 + fi + local ROLE="$1" + local TABLENAME="$2" + sql ${ROLE} "CREATE TABLE ${ROLE}.${TABLENAME} ( a int );" +} + + +function create_raster_table() { + if [[ $# -ne 2 ]] + then + log_error "create_raster_table requires two arguments: role and table_name" + exit 1 + fi + local RASTER_COL="the_raster_webmercator" + local ROLE="$1" + local TABLENAME="$2" + local OVERVIEW_TABLENAME="o_2_${TABLENAME}" + sql ${ROLE} "CREATE TABLE ${ROLE}.${TABLENAME} (rid serial PRIMARY KEY, ${RASTER_COL} raster);" + + sql ${ROLE} "CREATE TABLE ${ROLE}.${OVERVIEW_TABLENAME} (rid serial PRIMARY KEY, ${RASTER_COL} raster);" + + sql ${ROLE} "SELECT AddOverviewConstraints('${ROLE}','${OVERVIEW_TABLENAME}','${RASTER_COL}','${ROLE}','${TABLENAME}','${RASTER_COL}',2);" +} + +function drop_raster_table() { + if [[ $# -ne 2 ]] + then + log_error "drop_raster_table requires two arguments: role and table_name" + exit 1 + fi + local ROLE="$1" + local TABLENAME="$2" + local OVERVIEW_TABLENAME="o_2_${TABLENAME}" + + sql ${ROLE} "DROP TABLE ${ROLE}.${OVERVIEW_TABLENAME};" + sql ${ROLE} "DROP TABLE ${ROLE}.${TABLENAME};" +} + + +function setup() { + ${CMD} -c "CREATE DATABASE ${DATABASE}" + sql "CREATE SCHEMA cartodb;" + sql "GRANT USAGE ON SCHEMA cartodb TO public;" + sql "CREATE EXTENSION postgis;" + + log_info "########################### BOOTSTRAP ###########################" + ${CMD} -d ${DATABASE} -f scripts-available/CDB_Organizations.sql + # trick to allow forcing a schema when loading SQL files (see: http://bit.ly/1HeLnhL) + ${CMD} -d ${DATABASE} -f test/extension/run_at_cartodb_schema.sql + + + log_info "############################# SETUP #############################" + create_role_and_schema cdb_testmember_1 + create_role_and_schema cdb_testmember_2 + + create_table cdb_testmember_1 foo + sql cdb_testmember_1 'INSERT INTO cdb_testmember_1.foo VALUES (1), (2), (3), (4), (5), (6);' + sql cdb_testmember_1 'SELECT * FROM cdb_testmember_1.foo;' + + create_table cdb_testmember_2 bar + sql cdb_testmember_2 'INSERT INTO bar VALUES (1), (2), (3);' + sql cdb_testmember_2 'SELECT * FROM cdb_testmember_2.bar;' +} + +function tear_down() { + log_info "########################### USER TEAR DOWN ###########################" + sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2');" + sql cdb_testmember_2 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_2', 'bar', 'cdb_testmember_1');" + + sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.foo;' + sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.bar;' + + sql "DROP SCHEMA cartodb CASCADE" + + log_info "########################### TEAR DOWN ###########################" + sql 'DROP SCHEMA cdb_testmember_1;' + sql 'DROP SCHEMA cdb_testmember_2;' + + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM cdb_testmember_1;" + sql "REVOKE CONNECT ON DATABASE \"${DATABASE}\" FROM cdb_testmember_2;" + + sql 'DROP ROLE cdb_testmember_1;' + sql 'DROP ROLE cdb_testmember_2;' + + ${CMD} -c "DROP DATABASE ${DATABASE}" +} + +function run_tests() { + local FAILED_TESTS=() + + local TESTS + if [[ $# -ge 1 ]] + then + TESTS="$@" + else + TESTS=`cat $0 | perl -n -e'/function (test.*)\(\)/ && print "$1\n"'` + fi + for t in ${TESTS} + do + echo "####################################################################" + echo "#" + echo "# Running: ${t}" + echo "#" + echo "####################################################################" + clear_partial_result + setup + eval ${t} + if [[ ${PARTIALOK} -ne 0 ]] + then + FAILED_TESTS+=(${t}) + fi + tear_down + done + if [[ ${OK} -ne 0 ]] + then + echo + log_error "The following tests are failing:" + printf -- '\t%s\n' "${FAILED_TESTS[@]}" + fi +} + + +#################################################### TESTS GO HERE #################################################### + + +# Tests quota checking taking into account both geom and raster tables +function test_quota_for_each_user() { + # Normal tables add 4096 bytes + # Raster tables with overview constraints add 16384 bytes + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 4096 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 4096 + + create_raster_table cdb_testmember_1 raster_1 + create_raster_table cdb_testmember_2 raster_2 + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 20480 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 20480 + + create_raster_table cdb_testmember_1 raster_3 + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 36864 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 20480 + + drop_raster_table cdb_testmember_1 raster_1 + drop_raster_table cdb_testmember_2 raster_2 + drop_raster_table cdb_testmember_1 raster_3 + + sql cdb_testmember_1 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_1'::TEXT);" should 4096 + sql cdb_testmember_2 "SELECT cartodb.CDB_UserDataSize('cdb_testmember_2'::TEXT);" should 4096 +} + +#################################################### TESTS END HERE #################################################### + +run_tests $@ + +exit ${OK}