From 9500010a67db1a2688bfafa89279309fe10ccebb Mon Sep 17 00:00:00 2001 From: Kartones Date: Fri, 25 Jul 2014 10:52:46 +0200 Subject: [PATCH 1/7] CDB-3497 Partial splitting --- NEWS | 4 + scripts-available/CDB_CartodbfyTable.sql | 191 ++++++++++++++--------- 2 files changed, 118 insertions(+), 77 deletions(-) diff --git a/NEWS b/NEWS index 64dfd80..d85a46f 100644 --- a/NEWS +++ b/NEWS @@ -1,3 +1,7 @@ +0.3.2 (xxxx) +------------ +* Splitting of CartodbfyTable method in subfunctions to be able to call in fragments and evade timeouts + 0.3.1 (2014-07-22) ------------------ * Dummy version. We start using semantic versioning diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 7efb392..7f461de 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -23,6 +23,113 @@ BEGIN END; $$ LANGUAGE plpgsql VOLATILE; +-- Drop cartodb triggers (might prevent changing columns) +CREATE OR REPLACE FUNCTION _CDB_drop_triggers(reloid REGCLASS) +RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + -- "track_updates" + sql := 'DROP TRIGGER IF EXISTS track_updates ON ' || reloid::text; + EXECUTE sql; + + -- "update_the_geom_webmercator" + sql := 'DROP TRIGGER IF EXISTS update_the_geom_webmercator_trigger ON ' || reloid::text; + EXECUTE sql; + + -- "update_updated_at" + sql := 'DROP TRIGGER IF EXISTS update_updated_at_trigger ON ' || reloid::text; + EXECUTE sql; + + -- "test_quota" and "test_quota_per_row" + sql := 'DROP TRIGGER IF EXISTS test_quota ON ' || reloid::text; + EXECUTE sql; + sql := 'DROP TRIGGER IF EXISTS test_quota_per_row ON ' || reloid::text; + EXECUTE sql; +END; +$$ LANGUAGE PLPGSQL; + + +-- Create all triggers +-- NOTE: drop/create has the side-effect of re-enabling disabled triggers +CREATE OR REPLACE FUNCTION _CDB_create_triggers(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_the_geom_webmercator" +-- TODO: why _before_ and not after ? + sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON ' + || reloid::text + || ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()'; + 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; + +-- Initialize the_geom with values from the_geom_webmercator +-- do this only if the_geom_webmercator was found (not created) and the_geom was NOT found. +CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_from_the_geom_webmercator(reloid REGCLASS, geom_columns_exist BOOLEAN[]) +RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + IF geom_columns_exist[2] AND NOT geom_columns_exist[1] THEN + sql := 'UPDATE ' || reloid::text || ' SET the_geom = ST_Transform(the_geom_webmercator, 4326) '; + EXECUTE sql; + END IF; +END; +$$ LANGUAGE PLPGSQL; + +-- Initialize the_geom_webmercator with values from the_geom +-- do this only if the_geom was found (not created) and the_geom_webmercator was NOT found. +CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_webmercator_from_the_geom(reloid REGCLASS, geom_columns_exist BOOLEAN[]) + RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + IF geom_columns_exist[1] AND NOT geom_columns_exist[2] THEN + sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = public.CDB_TransformToWebmercator(the_geom) '; + EXECUTE sql; + END IF; +END; +$$ LANGUAGE PLPGSQL; + + +-- //////////////////////////////////////////////////// + -- Ensure a table is a "cartodb" table -- See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(schema_name TEXT, reloid REGCLASS) @@ -52,25 +159,7 @@ BEGIN RAISE EXCEPTION 'Please set user quota before cartodbfying tables.'; END; - -- Drop cartodb triggers (might prevent changing columns) - - -- "track_updates" - sql := 'DROP TRIGGER IF EXISTS track_updates ON ' || reloid::text; - EXECUTE sql; - - -- "update_the_geom_webmercator" - sql := 'DROP TRIGGER IF EXISTS update_the_geom_webmercator_trigger ON ' || reloid::text; - EXECUTE sql; - - -- "update_updated_at" - sql := 'DROP TRIGGER IF EXISTS update_updated_at_trigger ON ' || reloid::text; - EXECUTE sql; - - -- "test_quota" and "test_quota_per_row" - sql := 'DROP TRIGGER IF EXISTS test_quota ON ' || reloid::text; - EXECUTE sql; - sql := 'DROP TRIGGER IF EXISTS test_quota_per_row ON ' || reloid::text; - EXECUTE sql; + PERFORM public._CDB_drop_triggers(reloid); -- Ensure required fields exist @@ -229,8 +318,7 @@ BEGIN AND NOT a.attisdropped AND a.attname = rec.cname INTO STRICT rec2; IF rec2.oid NOT IN (1184) THEN -- timestamptz { - RAISE NOTICE 'Existing % field is of invalid type % (need timestamptz), renaming', rec. -cname, rec2.typname; + RAISE NOTICE 'Existing % field is of invalid type % (need timestamptz), renaming', rec.cname, rec2.typname; ELSE -- }{ -- Ensure data type is a TIMESTAMP WITH TIMEZONE sql := 'ALTER TABLE ' || reloid::text @@ -411,61 +499,11 @@ cname, rec2.typname; END LOOP; -- } on expected geometry columns - -- Initialize the_geom with values from the_geom_webmercator - -- do this only if the_geom_webmercator was found (not created) - -- _and_ the_geom was NOT found. - IF exists_geom_cols[2] AND NOT exists_geom_cols[1] THEN - sql := 'UPDATE ' || reloid::text || ' SET the_geom = ST_Transform(the_geom_webmercator, 4326) '; - EXECUTE sql; - END IF; + -- Both only populate if proceeds + PERFORM public._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols) + PERFORM public._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols) - -- Initialize the_geom_webmercator with values from the_geom - -- do this only if the_geom was found (not created) - -- _and_ the_geom_webmercator was NOT found. - IF exists_geom_cols[1] AND NOT exists_geom_cols[2] THEN - sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = public.CDB_TransformToWebmercator(the_geom) '; - EXECUTE sql; - END IF; - - -- Re-create all triggers - - -- NOTE: drop/create has the side-effect of re-enabling disabled triggers - - -- "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_the_geom_webmercator" - -- TODO: why _before_ and not after ? - sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON ' - || reloid::text - || ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()'; - 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; + PERFORM public._CDB_create_triggers(reloid); END; $$ LANGUAGE PLPGSQL; @@ -477,5 +515,4 @@ AS $$ BEGIN PERFORM public.CDB_CartodbfyTable('public', reloid); END; -$$ -LANGUAGE PLPGSQL; +$$ LANGUAGE PLPGSQL; From de2d3f818e6f0b56c7544d5f1263577a46cf8d54 Mon Sep 17 00:00:00 2001 From: Kartones Date: Fri, 25 Jul 2014 10:56:54 +0200 Subject: [PATCH 2/7] CDB-3497 Updating travis.yml to make it work with newer PG version --- .travis.yml | 1 + 1 file changed, 1 insertion(+) diff --git a/.travis.yml b/.travis.yml index 7bebe3f..2271e10 100644 --- a/.travis.yml +++ b/.travis.yml @@ -4,6 +4,7 @@ addons: postgresql: 9.3 before_install: + - sudo apt-get update #- sudo apt-get install -q postgresql-9.3-postgis-2.1 - sudo apt-get install -q postgresql-server-dev-9.3 - sudo apt-get install -q postgresql-plpython-9.3 From b5589fdf09cd8fc1b4767ac8c1be09686b4d6b00 Mon Sep 17 00:00:00 2001 From: Kartones Date: Fri, 25 Jul 2014 12:19:40 +0200 Subject: [PATCH 3/7] CDB-3497 --- scripts-available/CDB_CartodbfyTable.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 7f461de..e344805 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -500,8 +500,8 @@ BEGIN END LOOP; -- } on expected geometry columns -- Both only populate if proceeds - PERFORM public._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols) - PERFORM public._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols) + PERFORM public._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols); + PERFORM public._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols); PERFORM public._CDB_create_triggers(reloid); From f61d07518dfa1879812feea266f6020952f89562 Mon Sep 17 00:00:00 2001 From: Kartones Date: Mon, 28 Jul 2014 12:25:42 +0200 Subject: [PATCH 4/7] CDB-3497 ongoing splitting --- scripts-available/CDB_CartodbfyTable.sql | 477 ++++++++++++----------- 1 file changed, 246 insertions(+), 231 deletions(-) diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index e344805..968c7e7 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -53,7 +53,7 @@ $$ LANGUAGE PLPGSQL; -- Create all triggers -- NOTE: drop/create has the side-effect of re-enabling disabled triggers -CREATE OR REPLACE FUNCTION _CDB_create_triggers(reloid REGCLASS) +CREATE OR REPLACE FUNCTION _CDB_create_triggers(schema_name TEXT, reloid REGCLASS) RETURNS void AS $$ DECLARE @@ -115,7 +115,7 @@ $$ LANGUAGE PLPGSQL; -- Initialize the_geom_webmercator with values from the_geom -- do this only if the_geom was found (not created) and the_geom_webmercator was NOT found. CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_webmercator_from_the_geom(reloid REGCLASS, geom_columns_exist BOOLEAN[]) - RETURNS void +RETURNS void AS $$ DECLARE sql TEXT; @@ -127,6 +127,247 @@ BEGIN END; $$ LANGUAGE PLPGSQL; +CREATE OR REPLACE FUNCTION _CDB_create_cartodb_id_column(reloid REGCLASS) +RETURNS void +AS $$ +DECLARE + sql TEXT; + rec RECORD; + rec2 RECORD; + had_column BOOLEAN; + i INTEGER; + new_name TEXT; +BEGIN + << cartodb_id_setup >> + LOOP --{ + had_column := FALSE; + BEGIN + sql := 'ALTER TABLE ' || reloid::text || ' ADD cartodb_id SERIAL NOT NULL UNIQUE'; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + EXIT cartodb_id_setup; + EXCEPTION + WHEN duplicate_column THEN + RAISE NOTICE 'Column cartodb_id already exists'; + had_column := TRUE; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE; + END; + + IF had_column THEN + SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') + AS seq INTO rec2; + + -- Check data type is an integer + SELECT + pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') as seq, + t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a + WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = 'cartodb_id' + INTO STRICT rec; + + -- 20=int2, 21=int4, 23=int8 + IF rec.oid NOT IN (20,21,23) THEN -- { + RAISE NOTICE 'Existing cartodb_id field is of invalid type % (need int2, int4 or int8), renaming', rec.typname; + ELSIF rec.seq IS NULL THEN -- }{ + RAISE NOTICE 'Existing cartodb_id field does not have an associated sequence, renaming'; + ELSE -- }{ + sql := 'ALTER TABLE ' || reloid::text || ' ALTER COLUMN cartodb_id SET NOT NULL'; + IF NOT EXISTS ( SELECT c.conname FROM pg_constraint c, pg_attribute a + WHERE c.conkey = ARRAY[a.attnum] AND c.conrelid = reloid + AND a.attrelid = reloid + AND NOT a.attisdropped + AND a.attname = 'cartodb_id' + AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey + THEN + sql := sql || ', ADD unique(cartodb_id)'; + END IF; + BEGIN + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + EXIT cartodb_id_setup; + EXCEPTION + WHEN unique_violation OR not_null_violation THEN + RAISE NOTICE '%, renaming', SQLERRM; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE; + END; + END IF; -- } + + -- invalid column, need rename and re-create it + i := 0; + << rename_column >> + LOOP --{ + new_name := '_cartodb_id' || i; + BEGIN + sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN cartodb_id TO ' || new_name; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + EXCEPTION + WHEN duplicate_column THEN + i := i+1; + CONTINUE rename_column; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE; + END; + EXIT rename_column; + END LOOP; --} + CONTINUE cartodb_id_setup; + END IF; + END LOOP; -- } + + -- Try to copy data from new name if possible + IF new_name IS NOT NULL THEN + RAISE NOTICE 'Trying to recover data from % column', new_name; + BEGIN + -- Copy existing values to new field + -- NOTE: using ALTER is a workaround to a PostgreSQL bug and is also known to be faster for tables with many rows + -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost + sql := 'ALTER TABLE ' || reloid::text + || ' ALTER cartodb_id TYPE int USING ' + || new_name || '::int4'; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Find max value + sql := 'SELECT max(cartodb_id) FROM ' || reloid::text; + RAISE DEBUG 'Running %', sql; + EXECUTE sql INTO rec; + + -- Find sequence name + SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') + AS seq INTO rec2; + + -- Reset sequence name + sql := 'ALTER SEQUENCE ' || rec2.seq::text + || ' RESTART WITH ' || rec.max + 1; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Drop old column (all went fine if we got here) + sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + EXCEPTION + WHEN others THEN + RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)', + SQLERRM, SQLSTATE; + END; + END IF; + +END; +$$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION _CDB_create_timestamp_columns(reloid REGCLASS) + RETURNS void +AS $$ +DECLARE + sql TEXT; + rec RECORD; + rec2 RECORD; + had_column BOOLEAN; + i INTEGER; + new_name TEXT; +BEGIN + + FOR rec IN SELECT * FROM ( VALUES ('created_at'), ('updated_at') ) t(cname) + LOOP --{ + new_name := null; + << column_setup >> + LOOP --{ + had_column := FALSE; + BEGIN + sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname + || ' TIMESTAMPTZ NOT NULL DEFAULT now()'; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + EXIT column_setup; + EXCEPTION + WHEN duplicate_column THEN + RAISE NOTICE 'Column % already exists', rec.cname; + had_column := TRUE; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (%): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE; + END; + + IF had_column THEN + -- Check data type is a TIMESTAMP WITH TIMEZONE + SELECT t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a + WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = rec.cname + INTO STRICT rec2; + IF rec2.oid NOT IN (1184) THEN -- timestamptz { + RAISE NOTICE 'Existing % field is of invalid type % (need timestamptz), renaming', rec.cname, rec2.typname; + ELSE -- }{ + -- Ensure data type is a TIMESTAMP WITH TIMEZONE + sql := 'ALTER TABLE ' || reloid::text + || ' ALTER ' || rec.cname + || ' SET NOT NULL,' + || ' ALTER ' || rec.cname + || ' SET DEFAULT now()'; + BEGIN + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + EXIT column_setup; + EXCEPTION + WHEN not_null_violation THEN -- failed not-null + RAISE NOTICE '%, renaming', SQLERRM; + WHEN cannot_coerce THEN -- failed cast + RAISE NOTICE '%, renaming', SQLERRM; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (%): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE; + END; + END IF; -- } + + -- invalid column, need rename and re-create it + i := 0; + << rename_column >> + LOOP --{ + new_name := '_' || rec.cname || i; + BEGIN + sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + EXCEPTION + WHEN duplicate_column THEN + i := i+1; + CONTINUE rename_column; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (renaming %): % (%)', + reloid, rec.cname, SQLERRM, SQLSTATE; + END; + EXIT rename_column; + END LOOP; --} + CONTINUE column_setup; + END IF; + END LOOP; -- } + + -- Try to copy data from new name if possible + IF new_name IS NOT NULL THEN -- { + RAISE NOTICE 'Trying to recover data from % coumn', new_name; + BEGIN + -- Copy existing values to new field + -- NOTE: using ALTER is a workaround to a PostgreSQL bug and is also known to be faster for tables with many rows + -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost + sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname + || ' TYPE TIMESTAMPTZ USING ' + || new_name || '::timestamptz'; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Drop old column (all went find if we got here) + sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + EXCEPTION + WHEN others THEN + RAISE NOTICE 'Could not initialize % with existing values: % (%)', rec.cname, SQLERRM, SQLSTATE; + END; + END IF; -- } + END LOOP; -- } + +END; +$$ LANGUAGE PLPGSQL; -- //////////////////////////////////////////////////// @@ -163,235 +404,9 @@ BEGIN -- Ensure required fields exist - -- We need a cartodb_id column - << cartodb_id_setup >> - LOOP --{ - had_column := FALSE; - BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' ADD cartodb_id SERIAL NOT NULL UNIQUE'; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - EXIT cartodb_id_setup; - EXCEPTION - WHEN duplicate_column THEN - RAISE NOTICE 'Column cartodb_id already exists'; - had_column := TRUE; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', - reloid, SQLERRM, SQLSTATE; - END; + PERFORM public._CDB_create_cartodb_id_column(reloid); - IF had_column THEN - - SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') - AS seq INTO rec2; - - -- Check data type is an integer - SELECT - pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') as seq, - t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a - WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped - AND a.attname = 'cartodb_id' - INTO STRICT rec; - -- 20=int2, 21=int4, 23=int8 - IF rec.oid NOT IN (20,21,23) THEN -- { - RAISE NOTICE 'Existing cartodb_id field is of invalid type % (need int2, int4 or int8), renaming', rec.typname; - ELSIF rec.seq IS NULL THEN -- }{ - RAISE NOTICE 'Existing cartodb_id field does not have an associated sequence, renaming'; - ELSE -- }{ - sql := 'ALTER TABLE ' || reloid::text || ' ALTER COLUMN cartodb_id SET NOT NULL'; - IF NOT EXISTS ( SELECT c.conname FROM pg_constraint c, pg_attribute a - WHERE c.conkey = ARRAY[a.attnum] AND c.conrelid = reloid - AND a.attrelid = reloid - AND NOT a.attisdropped - AND a.attname = 'cartodb_id' - AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey - THEN - sql := sql || ', ADD unique(cartodb_id)'; - END IF; - BEGIN - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - EXIT cartodb_id_setup; - EXCEPTION - WHEN unique_violation OR not_null_violation THEN - RAISE NOTICE '%, renaming', SQLERRM; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', - reloid, SQLERRM, SQLSTATE; - END; - END IF; -- } - - - -- invalid column, need rename and re-create it - i := 0; - << rename_column >> - LOOP --{ - new_name := '_cartodb_id' || i; - BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN cartodb_id TO ' || new_name; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - EXCEPTION - WHEN duplicate_column THEN - i := i+1; - CONTINUE rename_column; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)', - reloid, SQLERRM, SQLSTATE; - END; - EXIT rename_column; - END LOOP; --} - CONTINUE cartodb_id_setup; - - END IF; - END LOOP; -- } - - -- Try to copy data from new name if possible - IF new_name IS NOT NULL THEN - RAISE NOTICE 'Trying to recover data from % column', new_name; - BEGIN - -- Copy existing values to new field - -- NOTE: using ALTER is a workaround to a PostgreSQL bug and - -- is also known to be faster for tables with many rows - -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost - sql := 'ALTER TABLE ' || reloid::text - || ' ALTER cartodb_id TYPE int USING ' - || new_name || '::int4'; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - - -- Find max value - sql := 'SELECT max(cartodb_id) FROM ' || reloid::text; - RAISE DEBUG 'Running %', sql; - EXECUTE sql INTO rec; - - -- Find sequence name - SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') - AS seq INTO rec2; - - -- Reset sequence name - sql := 'ALTER SEQUENCE ' || rec2.seq::text - || ' RESTART WITH ' || rec.max + 1; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - - -- Drop old column (all went find if we got here) - sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - - EXCEPTION - WHEN others THEN - RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)', - SQLERRM, SQLSTATE; - END; - END IF; - - -- We need created_at and updated_at - FOR rec IN SELECT * FROM ( VALUES ('created_at'), ('updated_at') ) t(cname) - LOOP --{ - new_name := null; - << column_setup >> - LOOP --{ - had_column := FALSE; - BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname - || ' TIMESTAMPTZ NOT NULL DEFAULT now()'; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - EXIT column_setup; - EXCEPTION - WHEN duplicate_column THEN - RAISE NOTICE 'Column % already exists', rec.cname; - had_column := TRUE; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (%): % (%)', - reloid, rec.cname, SQLERRM, SQLSTATE; - END; - - IF had_column THEN - - -- Check data type is a TIMESTAMP WITH TIMEZONE - SELECT t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a - WHERE a.atttypid = t.oid AND a.attrelid = reloid - AND NOT a.attisdropped AND a.attname = rec.cname - INTO STRICT rec2; - IF rec2.oid NOT IN (1184) THEN -- timestamptz { - RAISE NOTICE 'Existing % field is of invalid type % (need timestamptz), renaming', rec.cname, rec2.typname; - ELSE -- }{ - -- Ensure data type is a TIMESTAMP WITH TIMEZONE - sql := 'ALTER TABLE ' || reloid::text - || ' ALTER ' || rec.cname - || ' SET NOT NULL,' - || ' ALTER ' || rec.cname - || ' SET DEFAULT now()'; - BEGIN - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - EXIT column_setup; - EXCEPTION - WHEN not_null_violation THEN -- failed not-null - RAISE NOTICE '%, renaming', SQLERRM; - WHEN cannot_coerce THEN -- failed cast - RAISE NOTICE '%, renaming', SQLERRM; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (%): % (%)', - reloid, rec.cname, SQLERRM, SQLSTATE; - END; - END IF; -- } - - -- invalid column, need rename and re-create it - i := 0; - << rename_column >> - LOOP --{ - new_name := '_' || rec.cname || i; - BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - EXCEPTION - WHEN duplicate_column THEN - i := i+1; - CONTINUE rename_column; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (renaming %): % (%)', - reloid, rec.cname, SQLERRM, SQLSTATE; - END; - EXIT rename_column; - END LOOP; --} - CONTINUE column_setup; - - END IF; - END LOOP; -- } - - -- Try to copy data from new name if possible - IF new_name IS NOT NULL THEN -- { - RAISE NOTICE 'Trying to recover data from % coumn', new_name; - BEGIN - -- Copy existing values to new field - -- NOTE: using ALTER is a workaround to a PostgreSQL bug and - -- is also known to be faster for tables with many rows - -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost - sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname - || ' TYPE TIMESTAMPTZ USING ' - || new_name || '::timestamptz'; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - - -- Drop old column (all went find if we got here) - sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - - EXCEPTION - WHEN others THEN - RAISE NOTICE 'Could not initialize % with existing values: % (%)', - rec.cname, SQLERRM, SQLSTATE; - END; - END IF; -- } - - END LOOP; -- } + PERFORM public._CDB_create_timestamp_columns(reloid); -- We need the_geom and the_geom_webmercator FOR rec IN SELECT * FROM ( VALUES ('the_geom',4326), ('the_geom_webmercator',3857) ) t(cname,csrid) LOOP --{ @@ -503,7 +518,7 @@ BEGIN PERFORM public._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols); PERFORM public._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols); - PERFORM public._CDB_create_triggers(reloid); + PERFORM public._CDB_create_triggers(schema_name, reloid); END; $$ LANGUAGE PLPGSQL; From e5c8015e17b03394d76c84709815380fc80863f3 Mon Sep 17 00:00:00 2001 From: Kartones Date: Mon, 28 Jul 2014 13:11:51 +0200 Subject: [PATCH 5/7] CDB-3497 Splitted --- scripts-available/CDB_CartodbfyTable.sql | 159 ++++++++++++----------- 1 file changed, 85 insertions(+), 74 deletions(-) diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 968c7e7..89a1857 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -6,9 +6,31 @@ -- (user.rebuild_quota_trigger, called by rake task -- cartodb:db:update_test_quota_trigger) +-- Required checks before running cartodbfication +-- Either will pass silenty or raise an exception +CREATE OR REPLACE FUNCTION _CDB_check_prerequisites(schema_name TEXT, reloid REGCLASS) +RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + IF cartodb.schema_exists(schema_name) = false THEN + RAISE EXCEPTION 'Invalid schema name "%"', schema_name; + END IF; + + -- TODO: Check that user quota is set ? + 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.'; + END; +END; +$$ LANGUAGE PLPGSQL; + -- Update the_geom_webmercator CREATE OR REPLACE FUNCTION _CDB_update_the_geom_webmercator() -RETURNS trigger AS $$ +RETURNS trigger +AS $$ BEGIN NEW.the_geom_webmercator := public.CDB_TransformToWebmercator(NEW.the_geom); RETURN NEW; @@ -50,7 +72,6 @@ BEGIN END; $$ LANGUAGE PLPGSQL; - -- 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) @@ -369,51 +390,24 @@ BEGIN END; $$ LANGUAGE PLPGSQL; --- //////////////////////////////////////////////////// - --- Ensure a table is a "cartodb" table --- See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table -CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(schema_name TEXT, reloid REGCLASS) -RETURNS void +CREATE OR REPLACE FUNCTION _CDB_create_the_geom_columns(reloid REGCLASS) +RETURNS BOOLEAN[] AS $$ DECLARE sql TEXT; rec RECORD; rec2 RECORD; - tabinfo RECORD; had_column BOOLEAN; i INTEGER; new_name TEXT; - quota_in_bytes INT8; exists_geom_cols BOOLEAN[]; BEGIN - - IF cartodb.schema_exists(schema_name) = false THEN - RAISE EXCEPTION 'Invalid schema name "%"', schema_name; - END IF; - - -- TODO: Check that user quota is set ? - BEGIN - -- Content will be discarded - 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.'; - END; - - PERFORM public._CDB_drop_triggers(reloid); - - -- Ensure required fields exist - - PERFORM public._CDB_create_cartodb_id_column(reloid); - - PERFORM public._CDB_create_timestamp_columns(reloid); - -- We need the_geom and the_geom_webmercator FOR rec IN SELECT * FROM ( VALUES ('the_geom',4326), ('the_geom_webmercator',3857) ) t(cname,csrid) LOOP --{ << column_setup >> LOOP --{ BEGIN sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname - || ' GEOMETRY(geometry,' || rec.csrid || ')'; + || ' GEOMETRY(geometry,' || rec.csrid || ')'; RAISE DEBUG 'Running %', sql; EXECUTE sql; sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')'; @@ -421,25 +415,22 @@ BEGIN EXECUTE sql; exists_geom_cols := array_append(exists_geom_cols, false); EXIT column_setup; - EXCEPTION - WHEN duplicate_column THEN - exists_geom_cols := array_append(exists_geom_cols, true); - RAISE NOTICE 'Column % already exists', rec.cname; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (%): % (%)', - reloid, rec.cname, SQLERRM, SQLSTATE; + EXCEPTION + WHEN duplicate_column THEN + exists_geom_cols := array_append(exists_geom_cols, true); + RAISE NOTICE 'Column % already exists', rec.cname; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (%): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE; END; << column_fixup >> LOOP --{ - -- Check data type is a GEOMETRY SELECT t.typname, t.oid, a.attnotnull, - postgis_typmod_srid(a.atttypmod) as srid, - postgis_typmod_type(a.atttypmod) as gtype - FROM pg_type t, pg_attribute a - WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped - AND a.attname = rec.cname + postgis_typmod_srid(a.atttypmod) as srid, + postgis_typmod_type(a.atttypmod) as gtype + FROM pg_type t, pg_attribute a + WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = rec.cname INTO STRICT rec2; IF rec2.typname NOT IN ('geometry') THEN -- { @@ -448,46 +439,44 @@ BEGIN END IF; -- } IF rec2.srid != rec.csrid THEN -- { - BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname - || ' TYPE geometry(' || rec2.gtype || ',' || rec.csrid || ') USING ST_Transform(' - || rec.cname || ',' || rec.csrid || ')'; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; + BEGIN + sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname + || ' TYPE geometry(' || rec2.gtype || ',' || rec.csrid || ') USING ST_Transform(' + || rec.cname || ',' || rec.csrid || ')'; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; EXCEPTION WHEN others THEN RAISE NOTICE 'Could not enforce SRID % to column %: %, renaming', rec.csrid, rec.cname, SQLERRM; EXIT column_fixup; -- cannot fix, will rename - END; + END; END IF; -- } -- add gist indices if not there already IF NOT EXISTS ( SELECT ir.relname FROM pg_am am, pg_class ir, - pg_class c, pg_index i, - pg_attribute a + pg_class c, pg_index i, + pg_attribute a WHERE c.oid = reloid AND i.indrelid = c.oid - AND a.attname = rec.cname - AND i.indexrelid = ir.oid AND i.indnatts = 1 - AND i.indkey[0] = a.attnum AND a.attrelid = c.oid - AND NOT a.attisdropped AND am.oid = ir.relam - AND am.amname = 'gist' ) + AND a.attname = rec.cname + AND i.indexrelid = ir.oid AND i.indnatts = 1 + AND i.indkey[0] = a.attnum AND a.attrelid = c.oid + AND NOT a.attisdropped AND am.oid = ir.relam + AND am.amname = 'gist' ) THEN -- { BEGIN sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')'; RAISE DEBUG 'Running %', sql; EXECUTE sql; - EXCEPTION - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (% index): % (%)', - reloid, rec.cname, SQLERRM, SQLSTATE; + EXCEPTION + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (% index): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE; END; END IF; -- } -- if we reached this line, all went good EXIT column_setup; - - END LOOP; -- } column_fixup + END LOOP; -- } column_fixup -- invalid column, need rename and re-create it i := 0; @@ -498,22 +487,45 @@ BEGIN sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name; RAISE DEBUG 'Running %', sql; EXECUTE sql; - EXCEPTION - WHEN duplicate_column THEN - i := i+1; - CONTINUE rename_column; - WHEN others THEN - RAISE EXCEPTION 'Cartodbfying % (rename %): % (%)', - reloid, rec.cname, SQLERRM, SQLSTATE; + EXCEPTION + WHEN duplicate_column THEN + i := i+1; + CONTINUE rename_column; + WHEN others THEN + RAISE EXCEPTION 'Cartodbfying % (rename %): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE; END; EXIT rename_column; END LOOP; --} CONTINUE column_setup; - END LOOP; -- } column_setup + END LOOP; -- } column_setup END LOOP; -- } on expected geometry columns + SELECT exists_geom_cols; +END; +$$ LANGUAGE PLPGSQL; + +-- //////////////////////////////////////////////////// + +-- Ensure a table is a "cartodb" table +-- See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table +CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(schema_name TEXT, reloid REGCLASS) +RETURNS void +AS $$ +DECLARE + exists_geom_cols BOOLEAN[]; +BEGIN + + PERFORM public._CDB_check_prerequisites(schema_name, reloid); + + PERFORM public._CDB_drop_triggers(reloid); + + -- Ensure required fields exist + PERFORM public._CDB_create_cartodb_id_column(reloid); + PERFORM public._CDB_create_timestamp_columns(reloid); + SELECT public._CDB_create_the_geom_columns(reloid) INTO exists_geom_cols; + -- Both only populate if proceeds PERFORM public._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols); PERFORM public._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols); @@ -523,7 +535,6 @@ BEGIN END; $$ LANGUAGE PLPGSQL; - CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(reloid REGCLASS) RETURNS void AS $$ From 6d665ab163d9f69412714e715c41a42235fe6801 Mon Sep 17 00:00:00 2001 From: Kartones Date: Mon, 28 Jul 2014 15:16:19 +0200 Subject: [PATCH 6/7] CDB-3497 ongoing spec stabilization --- Makefile | 3 ++- scripts-available/CDB_CartodbfyTable.sql | 22 ++++++++++------------ 2 files changed, 12 insertions(+), 13 deletions(-) diff --git a/Makefile b/Makefile index 504a0b3..438bffa 100644 --- a/Makefile +++ b/Makefile @@ -1,7 +1,7 @@ # cartodb/Makefile EXTENSION = cartodb -EXTVERSION = 0.3.1 +EXTVERSION = 0.3.2 SED = sed @@ -20,6 +20,7 @@ UPGRADABLE = \ 0.2.0 \ 0.2.1 \ 0.3.0 \ + 0.3.0dev \ $(EXTVERSION)dev \ $(EXTVERSION)next \ $(END) diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 89a1857..968c3a6 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -497,12 +497,10 @@ BEGIN EXIT rename_column; END LOOP; --} CONTINUE column_setup; - END LOOP; -- } column_setup - END LOOP; -- } on expected geometry columns - SELECT exists_geom_cols; + RETURN exists_geom_cols; END; $$ LANGUAGE PLPGSQL; @@ -517,20 +515,20 @@ DECLARE exists_geom_cols BOOLEAN[]; BEGIN - PERFORM public._CDB_check_prerequisites(schema_name, reloid); + PERFORM cartodb._CDB_check_prerequisites(schema_name, reloid); - PERFORM public._CDB_drop_triggers(reloid); + PERFORM cartodb._CDB_drop_triggers(reloid); -- Ensure required fields exist - PERFORM public._CDB_create_cartodb_id_column(reloid); - PERFORM public._CDB_create_timestamp_columns(reloid); - SELECT public._CDB_create_the_geom_columns(reloid) INTO exists_geom_cols; + 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 public._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols); - PERFORM public._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols); + 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 public._CDB_create_triggers(schema_name, reloid); + PERFORM cartodb._CDB_create_triggers(schema_name, reloid); END; $$ LANGUAGE PLPGSQL; @@ -539,6 +537,6 @@ CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(reloid REGCLASS) RETURNS void AS $$ BEGIN - PERFORM public.CDB_CartodbfyTable('public', reloid); + PERFORM cartodb.CDB_CartodbfyTable('public', reloid); END; $$ LANGUAGE PLPGSQL; From 679af1d4a38aa93b3eca7544779e6096c464ef9a Mon Sep 17 00:00:00 2001 From: Kartones Date: Mon, 28 Jul 2014 17:53:19 +0200 Subject: [PATCH 7/7] CDB-3497 Finished stabilizing specs --- Makefile | 4 +- scripts-available/CDB_CartodbfyTable.sql | 208 ++++++++++++----------- test/CDB_CartodbfyTableTest_expect | 2 + 3 files changed, 115 insertions(+), 99 deletions(-) diff --git a/Makefile b/Makefile index 438bffa..04cda41 100644 --- a/Makefile +++ b/Makefile @@ -1,7 +1,7 @@ # cartodb/Makefile EXTENSION = cartodb -EXTVERSION = 0.3.2 +EXTVERSION = 0.3.3 SED = sed @@ -21,6 +21,8 @@ UPGRADABLE = \ 0.2.1 \ 0.3.0 \ 0.3.0dev \ + 0.3.1 \ + 0.3.2 \ $(EXTVERSION)dev \ $(EXTVERSION)next \ $(END) diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 968c3a6..783e62e 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -6,7 +6,7 @@ -- (user.rebuild_quota_trigger, called by rake task -- cartodb:db:update_test_quota_trigger) --- Required checks before running cartodbfication +-- 1) Required checks before running cartodbfication -- Either will pass silenty or raise an exception CREATE OR REPLACE FUNCTION _CDB_check_prerequisites(schema_name TEXT, reloid REGCLASS) RETURNS void @@ -27,27 +27,10 @@ BEGIN END; $$ LANGUAGE PLPGSQL; --- Update the_geom_webmercator -CREATE OR REPLACE FUNCTION _CDB_update_the_geom_webmercator() -RETURNS trigger -AS $$ -BEGIN - NEW.the_geom_webmercator := public.CDB_TransformToWebmercator(NEW.the_geom); - RETURN NEW; -END; -$$ LANGUAGE plpgsql VOLATILE; -CREATE OR REPLACE FUNCTION _CDB_update_updated_at() -RETURNS TRIGGER AS $$ -BEGIN - NEW.updated_at := now(); - RETURN NEW; -END; -$$ LANGUAGE plpgsql VOLATILE; - --- Drop cartodb triggers (might prevent changing columns) +-- 2) Drop cartodb triggers (might prevent changing columns) CREATE OR REPLACE FUNCTION _CDB_drop_triggers(reloid REGCLASS) -RETURNS void + RETURNS void AS $$ DECLARE sql TEXT; @@ -72,84 +55,10 @@ BEGIN END; $$ LANGUAGE PLPGSQL; --- 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 -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_the_geom_webmercator" --- TODO: why _before_ and not after ? - sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON ' - || reloid::text - || ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()'; - 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; - --- Initialize the_geom with values from the_geom_webmercator --- do this only if the_geom_webmercator was found (not created) and the_geom was NOT found. -CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_from_the_geom_webmercator(reloid REGCLASS, geom_columns_exist BOOLEAN[]) -RETURNS void -AS $$ -DECLARE - sql TEXT; -BEGIN - IF geom_columns_exist[2] AND NOT geom_columns_exist[1] THEN - sql := 'UPDATE ' || reloid::text || ' SET the_geom = ST_Transform(the_geom_webmercator, 4326) '; - EXECUTE sql; - END IF; -END; -$$ LANGUAGE PLPGSQL; - --- Initialize the_geom_webmercator with values from the_geom --- do this only if the_geom was found (not created) and the_geom_webmercator was NOT found. -CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_webmercator_from_the_geom(reloid REGCLASS, geom_columns_exist BOOLEAN[]) -RETURNS void -AS $$ -DECLARE - sql TEXT; -BEGIN - IF geom_columns_exist[1] AND NOT geom_columns_exist[2] THEN - sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = public.CDB_TransformToWebmercator(the_geom) '; - EXECUTE sql; - END IF; -END; -$$ LANGUAGE PLPGSQL; +-- 3) Cartodb_id creation & validation or renaming if invalid CREATE OR REPLACE FUNCTION _CDB_create_cartodb_id_column(reloid REGCLASS) -RETURNS void + RETURNS void AS $$ DECLARE sql TEXT; @@ -279,6 +188,8 @@ BEGIN END; $$ LANGUAGE PLPGSQL; + +-- 4) created_at and updated_at creation & validation or renaming if invalid CREATE OR REPLACE FUNCTION _CDB_create_timestamp_columns(reloid REGCLASS) RETURNS void AS $$ @@ -390,8 +301,10 @@ BEGIN END; $$ LANGUAGE PLPGSQL; + +-- 5) the_geom and the_geom_webmercator creation & validation or renaming if invalid CREATE OR REPLACE FUNCTION _CDB_create_the_geom_columns(reloid REGCLASS) -RETURNS BOOLEAN[] + RETURNS BOOLEAN[] AS $$ DECLARE sql TEXT; @@ -504,6 +417,105 @@ BEGIN END; $$ LANGUAGE PLPGSQL; + +-- 6) Initialize the_geom with values from the_geom_webmercator +-- do this only if the_geom_webmercator was found (not created) and the_geom was NOT found. +CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_from_the_geom_webmercator(reloid REGCLASS, geom_columns_exist BOOLEAN[]) + RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + IF geom_columns_exist[2] AND NOT geom_columns_exist[1] THEN + sql := 'UPDATE ' || reloid::text || ' SET the_geom = ST_Transform(the_geom_webmercator, 4326) '; + EXECUTE sql; + END IF; +END; +$$ LANGUAGE PLPGSQL; + + +-- 7) Initialize the_geom_webmercator with values from the_geom +-- do this only if the_geom was found (not created) and the_geom_webmercator was NOT found. +CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_webmercator_from_the_geom(reloid REGCLASS, geom_columns_exist BOOLEAN[]) + RETURNS void +AS $$ +DECLARE + sql TEXT; +BEGIN + IF geom_columns_exist[1] AND NOT geom_columns_exist[2] THEN + sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = public.CDB_TransformToWebmercator(the_geom) '; + EXECUTE sql; + END IF; +END; +$$ LANGUAGE PLPGSQL; + + +-- 8) 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 +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_the_geom_webmercator" +-- TODO: why _before_ and not after ? + sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON ' + || reloid::text + || ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()'; + 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() + RETURNS trigger +AS $$ +BEGIN + NEW.the_geom_webmercator := public.CDB_TransformToWebmercator(NEW.the_geom); + RETURN NEW; +END; +$$ LANGUAGE plpgsql VOLATILE; + +CREATE OR REPLACE FUNCTION _CDB_update_updated_at() + RETURNS TRIGGER AS $$ +BEGIN + NEW.updated_at := now(); + RETURN NEW; +END; +$$ LANGUAGE plpgsql VOLATILE; + + -- //////////////////////////////////////////////////// -- Ensure a table is a "cartodb" table @@ -529,7 +541,7 @@ BEGIN PERFORM cartodb._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols); PERFORM cartodb._CDB_create_triggers(schema_name, reloid); - + END; $$ LANGUAGE PLPGSQL; diff --git a/test/CDB_CartodbfyTableTest_expect b/test/CDB_CartodbfyTableTest_expect index c5e79e6..588102b 100644 --- a/test/CDB_CartodbfyTableTest_expect +++ b/test/CDB_CartodbfyTableTest_expect @@ -2,6 +2,8 @@ SET 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 0 single non-geometrical column cartodbfied fine DROP TABLE