Merge pull request #44 from CartoDB/CDB-3497

Cdb 3497
master 0.3.3
Kartones 10 years ago
commit b75b492490

@ -4,6 +4,7 @@ addons:
postgresql: 9.3 postgresql: 9.3
before_install: before_install:
- sudo apt-get update
#- sudo apt-get install -q postgresql-9.3-postgis-2.1 #- sudo apt-get install -q postgresql-9.3-postgis-2.1
- sudo apt-get update - sudo apt-get update
- sudo apt-get install -q postgresql-server-dev-9.3 - sudo apt-get install -q postgresql-server-dev-9.3

@ -1,7 +1,7 @@
# cartodb/Makefile # cartodb/Makefile
EXTENSION = cartodb EXTENSION = cartodb
EXTVERSION = 0.3.2 EXTVERSION = 0.3.3
SED = sed SED = sed
@ -22,6 +22,7 @@ UPGRADABLE = \
0.3.0 \ 0.3.0 \
0.3.0dev \ 0.3.0dev \
0.3.1 \ 0.3.1 \
0.3.2 \
$(EXTVERSION)dev \ $(EXTVERSION)dev \
$(EXTVERSION)next \ $(EXTVERSION)next \
$(END) $(END)

@ -1,3 +1,7 @@
0.3.3 (2014-07-xx)
------------------
* Splitting of CartodbfyTable method in subfunctions to be able to call in fragments and evade timeouts on hot zones
0.3.2 (2014-07-28) 0.3.2 (2014-07-28)
------------------ ------------------
* Make 0.3.0dev version upgradeable * Make 0.3.0dev version upgradeable

@ -6,54 +6,35 @@
-- (user.rebuild_quota_trigger, called by rake task -- (user.rebuild_quota_trigger, called by rake task
-- cartodb:db:update_test_quota_trigger) -- cartodb:db:update_test_quota_trigger)
-- Update the_geom_webmercator -- 1) Required checks before running cartodbfication
CREATE OR REPLACE FUNCTION _CDB_update_the_geom_webmercator() -- Either will pass silenty or raise an exception
RETURNS trigger AS $$ CREATE OR REPLACE FUNCTION _CDB_check_prerequisites(schema_name TEXT, reloid REGCLASS)
BEGIN RETURNS void
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
-- See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table
CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(schema_name TEXT, reloid REGCLASS)
RETURNS void
AS $$ AS $$
DECLARE DECLARE
sql TEXT; 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 BEGIN
IF cartodb.schema_exists(schema_name) = false THEN IF cartodb.schema_exists(schema_name) = false THEN
RAISE EXCEPTION 'Invalid schema name "%"', schema_name; RAISE EXCEPTION 'Invalid schema name "%"', schema_name;
END IF; END IF;
-- TODO: Check that user quota is set ? -- TODO: Check that user quota is set ?
BEGIN BEGIN
-- Content will be discarded
EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name::text) INTO sql; EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name::text) INTO sql;
EXCEPTION WHEN undefined_function THEN 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;
END;
$$ LANGUAGE PLPGSQL;
-- 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
AS $$
DECLARE
sql TEXT;
BEGIN
-- "track_updates" -- "track_updates"
sql := 'DROP TRIGGER IF EXISTS track_updates ON ' || reloid::text; sql := 'DROP TRIGGER IF EXISTS track_updates ON ' || reloid::text;
EXECUTE sql; EXECUTE sql;
@ -71,10 +52,22 @@ BEGIN
EXECUTE sql; EXECUTE sql;
sql := 'DROP TRIGGER IF EXISTS test_quota_per_row ON ' || reloid::text; sql := 'DROP TRIGGER IF EXISTS test_quota_per_row ON ' || reloid::text;
EXECUTE sql; EXECUTE sql;
END;
$$ LANGUAGE PLPGSQL;
-- Ensure required fields exist
-- We need a cartodb_id column -- 3) Cartodb_id creation & validation or renaming if invalid
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 >> << cartodb_id_setup >>
LOOP --{ LOOP --{
had_column := FALSE; had_column := FALSE;
@ -83,17 +76,15 @@ BEGIN
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXIT cartodb_id_setup; EXIT cartodb_id_setup;
EXCEPTION EXCEPTION
WHEN duplicate_column THEN WHEN duplicate_column THEN
RAISE NOTICE 'Column cartodb_id already exists'; RAISE NOTICE 'Column cartodb_id already exists';
had_column := TRUE; had_column := TRUE;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE;
reloid, SQLERRM, SQLSTATE;
END; END;
IF had_column THEN IF had_column THEN
SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id')
AS seq INTO rec2; AS seq INTO rec2;
@ -101,9 +92,9 @@ BEGIN
SELECT SELECT
pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') as seq, 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 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 WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = 'cartodb_id'
AND a.attname = 'cartodb_id'
INTO STRICT rec; INTO STRICT rec;
-- 20=int2, 21=int4, 23=int8 -- 20=int2, 21=int4, 23=int8
IF rec.oid NOT IN (20,21,23) THEN -- { 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; RAISE NOTICE 'Existing cartodb_id field is of invalid type % (need int2, int4 or int8), renaming', rec.typname;
@ -112,11 +103,11 @@ BEGIN
ELSE -- }{ ELSE -- }{
sql := 'ALTER TABLE ' || reloid::text || ' ALTER COLUMN cartodb_id SET NOT NULL'; 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 IF NOT EXISTS ( SELECT c.conname FROM pg_constraint c, pg_attribute a
WHERE c.conkey = ARRAY[a.attnum] AND c.conrelid = reloid WHERE c.conkey = ARRAY[a.attnum] AND c.conrelid = reloid
AND a.attrelid = reloid AND a.attrelid = reloid
AND NOT a.attisdropped AND NOT a.attisdropped
AND a.attname = 'cartodb_id' AND a.attname = 'cartodb_id'
AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey
THEN THEN
sql := sql || ', ADD unique(cartodb_id)'; sql := sql || ', ADD unique(cartodb_id)';
END IF; END IF;
@ -124,16 +115,14 @@ BEGIN
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXIT cartodb_id_setup; EXIT cartodb_id_setup;
EXCEPTION EXCEPTION
WHEN unique_violation OR not_null_violation THEN WHEN unique_violation OR not_null_violation THEN
RAISE NOTICE '%, renaming', SQLERRM; RAISE NOTICE '%, renaming', SQLERRM;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE;
reloid, SQLERRM, SQLSTATE;
END; END;
END IF; -- } END IF; -- }
-- invalid column, need rename and re-create it -- invalid column, need rename and re-create it
i := 0; i := 0;
<< rename_column >> << rename_column >>
@ -143,32 +132,29 @@ BEGIN
sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN cartodb_id TO ' || new_name; sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN cartodb_id TO ' || new_name;
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXCEPTION EXCEPTION
WHEN duplicate_column THEN WHEN duplicate_column THEN
i := i+1; i := i+1;
CONTINUE rename_column; CONTINUE rename_column;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)', RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE;
reloid, SQLERRM, SQLSTATE;
END; END;
EXIT rename_column; EXIT rename_column;
END LOOP; --} END LOOP; --}
CONTINUE cartodb_id_setup; CONTINUE cartodb_id_setup;
END IF; END IF;
END LOOP; -- } END LOOP; -- }
-- Try to copy data from new name if possible -- Try to copy data from new name if possible
IF new_name IS NOT NULL THEN IF new_name IS NOT NULL THEN
RAISE NOTICE 'Trying to recover data from % column', new_name; RAISE NOTICE 'Trying to recover data from % column', new_name;
BEGIN BEGIN
-- Copy existing values to new field -- Copy existing values to new field
-- NOTE: using ALTER is a workaround to a PostgreSQL bug and -- NOTE: using ALTER is a workaround to a PostgreSQL bug and is also known to be faster for tables with many rows
-- is also known to be faster for tables with many rows
-- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost
sql := 'ALTER TABLE ' || reloid::text sql := 'ALTER TABLE ' || reloid::text
|| ' ALTER cartodb_id TYPE int USING ' || ' ALTER cartodb_id TYPE int USING '
|| new_name || '::int4'; || new_name || '::int4';
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
@ -183,23 +169,39 @@ BEGIN
-- Reset sequence name -- Reset sequence name
sql := 'ALTER SEQUENCE ' || rec2.seq::text sql := 'ALTER SEQUENCE ' || rec2.seq::text
|| ' RESTART WITH ' || rec.max + 1; || ' RESTART WITH ' || rec.max + 1;
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
-- Drop old column (all went find if we got here) -- Drop old column (all went fine if we got here)
sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name; sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name;
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXCEPTION EXCEPTION
WHEN others THEN WHEN others THEN
RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)', RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)',
SQLERRM, SQLSTATE; SQLERRM, SQLSTATE;
END; END;
END IF; END IF;
-- We need created_at and updated_at 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 $$
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) FOR rec IN SELECT * FROM ( VALUES ('created_at'), ('updated_at') ) t(cname)
LOOP --{ LOOP --{
new_name := null; new_name := null;
@ -208,48 +210,43 @@ BEGIN
had_column := FALSE; had_column := FALSE;
BEGIN BEGIN
sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname
|| ' TIMESTAMPTZ NOT NULL DEFAULT now()'; || ' TIMESTAMPTZ NOT NULL DEFAULT now()';
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXIT column_setup; EXIT column_setup;
EXCEPTION EXCEPTION
WHEN duplicate_column THEN WHEN duplicate_column THEN
RAISE NOTICE 'Column % already exists', rec.cname; RAISE NOTICE 'Column % already exists', rec.cname;
had_column := TRUE; had_column := TRUE;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (%): % (%)', RAISE EXCEPTION 'Cartodbfying % (%): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
reloid, rec.cname, SQLERRM, SQLSTATE;
END; END;
IF had_column THEN IF had_column THEN
-- Check data type is a TIMESTAMP WITH TIMEZONE -- Check data type is a TIMESTAMP WITH TIMEZONE
SELECT t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a SELECT t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a
WHERE a.atttypid = t.oid AND a.attrelid = reloid WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = rec.cname
AND NOT a.attisdropped AND a.attname = rec.cname
INTO STRICT rec2; INTO STRICT rec2;
IF rec2.oid NOT IN (1184) THEN -- timestamptz { IF rec2.oid NOT IN (1184) THEN -- timestamptz {
RAISE NOTICE 'Existing % field is of invalid type % (need timestamptz), renaming', rec. RAISE NOTICE 'Existing % field is of invalid type % (need timestamptz), renaming', rec.cname, rec2.typname;
cname, rec2.typname;
ELSE -- }{ ELSE -- }{
-- Ensure data type is a TIMESTAMP WITH TIMEZONE -- Ensure data type is a TIMESTAMP WITH TIMEZONE
sql := 'ALTER TABLE ' || reloid::text sql := 'ALTER TABLE ' || reloid::text
|| ' ALTER ' || rec.cname || ' ALTER ' || rec.cname
|| ' SET NOT NULL,' || ' SET NOT NULL,'
|| ' ALTER ' || rec.cname || ' ALTER ' || rec.cname
|| ' SET DEFAULT now()'; || ' SET DEFAULT now()';
BEGIN BEGIN
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXIT column_setup; EXIT column_setup;
EXCEPTION EXCEPTION
WHEN not_null_violation THEN -- failed not-null WHEN not_null_violation THEN -- failed not-null
RAISE NOTICE '%, renaming', SQLERRM; RAISE NOTICE '%, renaming', SQLERRM;
WHEN cannot_coerce THEN -- failed cast WHEN cannot_coerce THEN -- failed cast
RAISE NOTICE '%, renaming', SQLERRM; RAISE NOTICE '%, renaming', SQLERRM;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (%): % (%)', RAISE EXCEPTION 'Cartodbfying % (%): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
reloid, rec.cname, SQLERRM, SQLSTATE;
END; END;
END IF; -- } END IF; -- }
@ -262,18 +259,17 @@ cname, rec2.typname;
sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name; sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name;
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXCEPTION EXCEPTION
WHEN duplicate_column THEN WHEN duplicate_column THEN
i := i+1; i := i+1;
CONTINUE rename_column; CONTINUE rename_column;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (renaming %): % (%)', RAISE EXCEPTION 'Cartodbfying % (renaming %): % (%)',
reloid, rec.cname, SQLERRM, SQLSTATE; reloid, rec.cname, SQLERRM, SQLSTATE;
END; END;
EXIT rename_column; EXIT rename_column;
END LOOP; --} END LOOP; --}
CONTINUE column_setup; CONTINUE column_setup;
END IF; END IF;
END LOOP; -- } END LOOP; -- }
@ -282,12 +278,11 @@ cname, rec2.typname;
RAISE NOTICE 'Trying to recover data from % coumn', new_name; RAISE NOTICE 'Trying to recover data from % coumn', new_name;
BEGIN BEGIN
-- Copy existing values to new field -- Copy existing values to new field
-- NOTE: using ALTER is a workaround to a PostgreSQL bug and -- NOTE: using ALTER is a workaround to a PostgreSQL bug and is also known to be faster for tables with many rows
-- is also known to be faster for tables with many rows
-- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost
sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname
|| ' TYPE TIMESTAMPTZ USING ' || ' TYPE TIMESTAMPTZ USING '
|| new_name || '::timestamptz'; || new_name || '::timestamptz';
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
@ -296,21 +291,36 @@ cname, rec2.typname;
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXCEPTION EXCEPTION
WHEN others THEN WHEN others THEN
RAISE NOTICE 'Could not initialize % with existing values: % (%)', RAISE NOTICE 'Could not initialize % with existing values: % (%)', rec.cname, SQLERRM, SQLSTATE;
rec.cname, SQLERRM, SQLSTATE;
END; END;
END IF; -- } END IF; -- }
END LOOP; -- } END LOOP; -- }
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[]
AS $$
DECLARE
sql TEXT;
rec RECORD;
rec2 RECORD;
had_column BOOLEAN;
i INTEGER;
new_name TEXT;
exists_geom_cols BOOLEAN[];
BEGIN
-- We need the_geom and the_geom_webmercator -- 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 --{ FOR rec IN SELECT * FROM ( VALUES ('the_geom',4326), ('the_geom_webmercator',3857) ) t(cname,csrid) LOOP --{
<< column_setup >> LOOP --{ << column_setup >> LOOP --{
BEGIN BEGIN
sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname
|| ' GEOMETRY(geometry,' || rec.csrid || ')'; || ' GEOMETRY(geometry,' || rec.csrid || ')';
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')'; sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')';
@ -318,25 +328,22 @@ cname, rec2.typname;
EXECUTE sql; EXECUTE sql;
exists_geom_cols := array_append(exists_geom_cols, false); exists_geom_cols := array_append(exists_geom_cols, false);
EXIT column_setup; EXIT column_setup;
EXCEPTION EXCEPTION
WHEN duplicate_column THEN WHEN duplicate_column THEN
exists_geom_cols := array_append(exists_geom_cols, true); exists_geom_cols := array_append(exists_geom_cols, true);
RAISE NOTICE 'Column % already exists', rec.cname; RAISE NOTICE 'Column % already exists', rec.cname;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (%): % (%)', RAISE EXCEPTION 'Cartodbfying % (%): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
reloid, rec.cname, SQLERRM, SQLSTATE;
END; END;
<< column_fixup >> << column_fixup >>
LOOP --{ LOOP --{
-- Check data type is a GEOMETRY -- Check data type is a GEOMETRY
SELECT t.typname, t.oid, a.attnotnull, SELECT t.typname, t.oid, a.attnotnull,
postgis_typmod_srid(a.atttypmod) as srid, postgis_typmod_srid(a.atttypmod) as srid,
postgis_typmod_type(a.atttypmod) as gtype postgis_typmod_type(a.atttypmod) as gtype
FROM pg_type t, pg_attribute a FROM pg_type t, pg_attribute a
WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = rec.cname
AND a.attname = rec.cname
INTO STRICT rec2; INTO STRICT rec2;
IF rec2.typname NOT IN ('geometry') THEN -- { IF rec2.typname NOT IN ('geometry') THEN -- {
@ -345,46 +352,44 @@ cname, rec2.typname;
END IF; -- } END IF; -- }
IF rec2.srid != rec.csrid THEN -- { IF rec2.srid != rec.csrid THEN -- {
BEGIN BEGIN
sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname
|| ' TYPE geometry(' || rec2.gtype || ',' || rec.csrid || ') USING ST_Transform(' || ' TYPE geometry(' || rec2.gtype || ',' || rec.csrid || ') USING ST_Transform('
|| rec.cname || ',' || rec.csrid || ')'; || rec.cname || ',' || rec.csrid || ')';
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXCEPTION EXCEPTION
WHEN others THEN WHEN others THEN
RAISE NOTICE 'Could not enforce SRID % to column %: %, renaming', rec.csrid, rec.cname, SQLERRM; RAISE NOTICE 'Could not enforce SRID % to column %: %, renaming', rec.csrid, rec.cname, SQLERRM;
EXIT column_fixup; -- cannot fix, will rename EXIT column_fixup; -- cannot fix, will rename
END; END;
END IF; -- } END IF; -- }
-- add gist indices if not there already -- add gist indices if not there already
IF NOT EXISTS ( SELECT ir.relname IF NOT EXISTS ( SELECT ir.relname
FROM pg_am am, pg_class ir, FROM pg_am am, pg_class ir,
pg_class c, pg_index i, pg_class c, pg_index i,
pg_attribute a pg_attribute a
WHERE c.oid = reloid AND i.indrelid = c.oid WHERE c.oid = reloid AND i.indrelid = c.oid
AND a.attname = rec.cname AND a.attname = rec.cname
AND i.indexrelid = ir.oid AND i.indnatts = 1 AND i.indexrelid = ir.oid AND i.indnatts = 1
AND i.indkey[0] = a.attnum AND a.attrelid = c.oid AND i.indkey[0] = a.attnum AND a.attrelid = c.oid
AND NOT a.attisdropped AND am.oid = ir.relam AND NOT a.attisdropped AND am.oid = ir.relam
AND am.amname = 'gist' ) AND am.amname = 'gist' )
THEN -- { THEN -- {
BEGIN BEGIN
sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')'; sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')';
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXCEPTION EXCEPTION
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (% index): % (%)', RAISE EXCEPTION 'Cartodbfying % (% index): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
reloid, rec.cname, SQLERRM, SQLSTATE;
END; END;
END IF; -- } END IF; -- }
-- if we reached this line, all went good -- if we reached this line, all went good
EXIT column_setup; EXIT column_setup;
END LOOP; -- } column_fixup
END LOOP; -- } column_fixup
-- invalid column, need rename and re-create it -- invalid column, need rename and re-create it
i := 0; i := 0;
@ -395,87 +400,155 @@ cname, rec2.typname;
sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name; sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name;
RAISE DEBUG 'Running %', sql; RAISE DEBUG 'Running %', sql;
EXECUTE sql; EXECUTE sql;
EXCEPTION EXCEPTION
WHEN duplicate_column THEN WHEN duplicate_column THEN
i := i+1; i := i+1;
CONTINUE rename_column; CONTINUE rename_column;
WHEN others THEN WHEN others THEN
RAISE EXCEPTION 'Cartodbfying % (rename %): % (%)', RAISE EXCEPTION 'Cartodbfying % (rename %): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
reloid, rec.cname, SQLERRM, SQLSTATE;
END; END;
EXIT rename_column; EXIT rename_column;
END LOOP; --} END LOOP; --}
CONTINUE column_setup; CONTINUE column_setup;
END LOOP; -- } column_setup
END LOOP; -- } on expected geometry columns
END LOOP; -- } column_setup RETURN exists_geom_cols;
END;
$$ LANGUAGE PLPGSQL;
END LOOP; -- } on expected geometry columns
-- Initialize the_geom with values from the_geom_webmercator -- 6) Initialize the_geom with values from the_geom_webmercator
-- do this only if the_geom_webmercator was found (not created) -- do this only if the_geom_webmercator was found (not created) and the_geom was NOT found.
-- _and_ the_geom was NOT found. CREATE OR REPLACE FUNCTION _CDB_populate_the_geom_from_the_geom_webmercator(reloid REGCLASS, geom_columns_exist BOOLEAN[])
IF exists_geom_cols[2] AND NOT exists_geom_cols[1] THEN 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) '; sql := 'UPDATE ' || reloid::text || ' SET the_geom = ST_Transform(the_geom_webmercator, 4326) ';
EXECUTE sql; EXECUTE sql;
END IF; END IF;
END;
$$ LANGUAGE PLPGSQL;
-- Initialize the_geom_webmercator with values from the_geom -- 7) Initialize the_geom_webmercator with values from the_geom
-- do this only if the_geom was found (not created) -- do this only if the_geom was found (not created) and the_geom_webmercator was NOT found.
-- _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[])
IF exists_geom_cols[1] AND NOT exists_geom_cols[2] THEN 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) '; sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = public.CDB_TransformToWebmercator(the_geom) ';
EXECUTE sql; EXECUTE sql;
END IF; END IF;
END;
$$ LANGUAGE PLPGSQL;
-- Re-create all triggers
-- NOTE: drop/create has the side-effect of re-enabling disabled triggers
-- "track_updates" -- 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 ' sql := 'CREATE trigger track_updates AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE ON '
|| reloid::text || reloid::text
|| ' FOR EACH STATEMENT EXECUTE PROCEDURE public.cdb_tablemetadata_trigger()'; || ' FOR EACH STATEMENT EXECUTE PROCEDURE public.cdb_tablemetadata_trigger()';
EXECUTE sql; EXECUTE sql;
-- "update_the_geom_webmercator" -- "update_the_geom_webmercator"
-- TODO: why _before_ and not after ? -- TODO: why _before_ and not after ?
sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON ' sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON '
|| reloid::text || reloid::text
|| ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()'; || ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()';
EXECUTE sql; EXECUTE sql;
-- "update_updated_at" -- "update_updated_at"
-- TODO: why _before_ and not after ? -- TODO: why _before_ and not after ?
sql := 'CREATE trigger update_updated_at_trigger BEFORE UPDATE ON ' sql := 'CREATE trigger update_updated_at_trigger BEFORE UPDATE ON '
|| reloid::text || reloid::text
|| ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_updated_at()'; || ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_updated_at()';
EXECUTE sql; EXECUTE sql;
-- "test_quota" and "test_quota_per_row" -- "test_quota" and "test_quota_per_row"
sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON ' sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON '
|| reloid::text || reloid::text
|| ' EXECUTE PROCEDURE public.CDB_CheckQuota(1, ''-1'', ''' || ' EXECUTE PROCEDURE public.CDB_CheckQuota(1, ''-1'', '''
|| schema_name::text || schema_name::text
|| ''')'; || ''')';
EXECUTE sql; EXECUTE sql;
sql := 'CREATE TRIGGER test_quota_per_row BEFORE UPDATE OR INSERT ON ' sql := 'CREATE TRIGGER test_quota_per_row BEFORE UPDATE OR INSERT ON '
|| reloid::text || reloid::text
|| ' FOR EACH ROW EXECUTE PROCEDURE public.CDB_CheckQuota(0.001, ''-1'', ''' || ' FOR EACH ROW EXECUTE PROCEDURE public.CDB_CheckQuota(0.001, ''-1'', '''
|| schema_name::text || schema_name::text
|| ''')'; || ''')';
EXECUTE sql; EXECUTE sql;
END; END;
$$ LANGUAGE PLPGSQL; $$ 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
-- 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 cartodb._CDB_check_prerequisites(schema_name, reloid);
PERFORM cartodb._CDB_drop_triggers(reloid);
-- 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);
PERFORM cartodb._CDB_create_triggers(schema_name, reloid);
END;
$$ LANGUAGE PLPGSQL;
CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(reloid REGCLASS) CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(reloid REGCLASS)
RETURNS void RETURNS void
AS $$ AS $$
BEGIN BEGIN
PERFORM public.CDB_CartodbfyTable('public', reloid); PERFORM cartodb.CDB_CartodbfyTable('public', reloid);
END; END;
$$ $$ LANGUAGE PLPGSQL;
LANGUAGE PLPGSQL;

@ -2,6 +2,8 @@ SET
CREATE FUNCTION CREATE FUNCTION
SELECT 1 SELECT 1
ERROR: Please set user quota before cartodbfying tables. 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 0
single non-geometrical column cartodbfied fine single non-geometrical column cartodbfied fine
DROP TABLE DROP TABLE

Loading…
Cancel
Save