diff --git a/Makefile b/Makefile index b0241fd..f269c4f 100644 --- a/Makefile +++ b/Makefile @@ -1,7 +1,7 @@ # cartodb/Makefile EXTENSION = cartodb -EXTVERSION = 0.8.3 +EXTVERSION = 0.9.0 SED = sed @@ -42,6 +42,7 @@ UPGRADABLE = \ 0.8.0 \ 0.8.1 \ 0.8.2 \ + 0.9.0 \ $(EXTVERSION)dev \ $(EXTVERSION)next \ $(END) diff --git a/NEWS.md b/NEWS.md index 6d68994..dbdcd76 100644 --- a/NEWS.md +++ b/NEWS.md @@ -1,4 +1,19 @@ -0.8.3 (2015-mm-dd) +0.9.0 (2015-08-19) +------------------ +* Re-implementation of `CDB_CartodbfyTable` functions + - The signature of the main function changes to + ``` + FUNCTION CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS) + RETURNS REGCLASS + ``` + - The `destschema` does not need to match the origin schema of `reloid` + - It returns the `regclass` of the cartodbfy'ed table, if it needs to be rewritten. + - There are many optimizations + - The columns `created_at` and `updated_at` will no longer be added +* Fix for CDB_UserDataSize failing due `ERROR: relation "*" does not exist.` #110 +* Review test to validate permissions in public tables [#112](https://github.com/CartoDB/cartodb-postgresql/pull/112) + +0.8.3 (2015-08-14) ------------------ * Fixes CDB_UserDataSize failing due `ERROR: relation "*" does not exist.` [#108](https://github.com/CartoDB/cartodb-postgresql/issues/108) diff --git a/expected/test_ddl_triggers.out b/expected/test_ddl_triggers.out index 737468a..c8786c9 100644 --- a/expected/test_ddl_triggers.out +++ b/expected/test_ddl_triggers.out @@ -25,6 +25,8 @@ SELECT CDB_SetUserQuotaInBytes('c', 0); 0 (1 row) +DROP USER IF EXISTS cartodb_postgresql_unpriv_user; +NOTICE: role "cartodb_postgresql_unpriv_user" does not exist, skipping CREATE USER cartodb_postgresql_unpriv_user; GRANT ALL ON SCHEMA c to cartodb_postgresql_unpriv_user; SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; @@ -36,7 +38,6 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; select 1 as i INTO c.t3; NOTICE: trigger "track_updates" for table "c.t3" does not exist, skipping NOTICE: trigger "update_the_geom_webmercator_trigger" for table "c.t3" does not exist, skipping -NOTICE: trigger "update_updated_at_trigger" for table "c.t3" does not exist, skipping NOTICE: trigger "test_quota" for table "c.t3" does not exist, skipping NOTICE: trigger "test_quota_per_row" for table "c.t3" does not exist, skipping NOTICE: event trigger "cdb_on_relation_create" does not exist, skipping @@ -45,17 +46,6 @@ NOTICE: event trigger "cdb_on_alter_column" does not exist, skipping NOTICE: event trigger "cdb_on_drop_column" does not exist, skipping NOTICE: event trigger "cdb_on_add_column" does not exist, skipping NOTICE: cdb_invalidate_varnish(c.t3) called -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i -from c.t3; - cartodb_id | c=u | u<1s | the_geom | the_geom_webmercator | i -------------+-----+------+----------+----------------------+--- - 1 | t | t | | | 1 -(1 row) - RESET SESSION AUTHORIZATION; select tabname::text, @@ -72,28 +62,14 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; select 1 as cartodb_id INTO c.t4; NOTICE: trigger "track_updates" for table "c.t4" does not exist, skipping NOTICE: trigger "update_the_geom_webmercator_trigger" for table "c.t4" does not exist, skipping -NOTICE: trigger "update_updated_at_trigger" for table "c.t4" does not exist, skipping NOTICE: trigger "test_quota" for table "c.t4" does not exist, skipping NOTICE: trigger "test_quota_per_row" for table "c.t4" does not exist, skipping -NOTICE: Column cartodb_id already exists -NOTICE: Existing cartodb_id field does not have an associated sequence, renaming -NOTICE: Trying to recover data from _cartodb_id0 column NOTICE: event trigger "cdb_on_relation_create" does not exist, skipping NOTICE: event trigger "cdb_on_relation_drop" does not exist, skipping NOTICE: event trigger "cdb_on_alter_column" does not exist, skipping NOTICE: event trigger "cdb_on_drop_column" does not exist, skipping NOTICE: event trigger "cdb_on_add_column" does not exist, skipping NOTICE: cdb_invalidate_varnish(c.t4) called -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator -from c.t4; - cartodb_id | c=u | u<1s | the_geom | the_geom_webmercator -------------+-----+------+----------+---------------------- - 1 | t | t | | -(1 row) - RESET SESSION AUTHORIZATION; select tabname::text, @@ -115,27 +91,12 @@ select pg_sleep(.1); (1 row) alter table c.t3 rename column the_geom_webmercator to webmerc; -NOTICE: Column cartodb_id already exists -NOTICE: Column created_at already exists -NOTICE: Column updated_at already exists -NOTICE: Column the_geom already exists NOTICE: event trigger "cdb_on_relation_create" does not exist, skipping NOTICE: event trigger "cdb_on_relation_drop" does not exist, skipping NOTICE: event trigger "cdb_on_alter_column" does not exist, skipping NOTICE: event trigger "cdb_on_drop_column" does not exist, skipping NOTICE: event trigger "cdb_on_add_column" does not exist, skipping NOTICE: cdb_invalidate_varnish(c.t3) called -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc -from c.t3; - cartodb_id | c=u | u<1s | the_geom | the_geom_webmercator | i | webmerc -------------+-----+------+----------+----------------------+---+--------- - 1 | t | t | | | 1 | -(1 row) - RESET SESSION AUTHORIZATION; select tabname::text, @@ -154,27 +115,12 @@ select pg_sleep(.1); (1 row) alter table c.t3 rename column the_geom_webmercator to webmerc2; -NOTICE: Column cartodb_id already exists -NOTICE: Column created_at already exists -NOTICE: Column updated_at already exists -NOTICE: Column the_geom already exists NOTICE: event trigger "cdb_on_relation_create" does not exist, skipping NOTICE: event trigger "cdb_on_relation_drop" does not exist, skipping NOTICE: event trigger "cdb_on_alter_column" does not exist, skipping NOTICE: event trigger "cdb_on_drop_column" does not exist, skipping NOTICE: event trigger "cdb_on_add_column" does not exist, skipping NOTICE: cdb_invalidate_varnish(c.t3) called -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc, webmerc2 -from c.t3; - cartodb_id | c=u | u<1s | the_geom | the_geom_webmercator | i | webmerc | webmerc2 -------------+-----+------+----------+----------------------+---+---------+---------- - 1 | t | t | | | 1 | | -(1 row) - RESET SESSION AUTHORIZATION; select tabname::text, @@ -196,27 +142,12 @@ select pg_sleep(.1); (1 row) alter table c.t3 drop column the_geom_webmercator; -NOTICE: Column cartodb_id already exists -NOTICE: Column created_at already exists -NOTICE: Column updated_at already exists -NOTICE: Column the_geom already exists NOTICE: event trigger "cdb_on_relation_create" does not exist, skipping NOTICE: event trigger "cdb_on_relation_drop" does not exist, skipping NOTICE: event trigger "cdb_on_alter_column" does not exist, skipping NOTICE: event trigger "cdb_on_drop_column" does not exist, skipping NOTICE: event trigger "cdb_on_add_column" does not exist, skipping NOTICE: cdb_invalidate_varnish(c.t3) called -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc, webmerc2 -from c.t3; - cartodb_id | c=u | u<1s | the_geom | the_geom_webmercator | i | webmerc | webmerc2 -------------+-----+------+----------+----------------------+---+---------+---------- - 1 | t | t | | | 1 | | -(1 row) - RESET SESSION AUTHORIZATION; select tabname::text, @@ -239,17 +170,6 @@ select pg_sleep(.1); alter table c.t3 add column id2 int; NOTICE: cdb_invalidate_varnish(c.t3) called -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc, webmerc2, id2 -from c.t3; - cartodb_id | c=u | u<1s | the_geom | the_geom_webmercator | i | webmerc | webmerc2 | id2 -------------+-----+------+----------+----------------------+---+---------+----------+----- - 1 | t | t | | | 1 | | | -(1 row) - RESET SESSION AUTHORIZATION; select tabname::text, @@ -272,5 +192,6 @@ select count(*) from CDB_TableMetadata; 0 (1 row) -DROP USER cartodb_postgresql_unpriv_user; +DROP OWNED BY cartodb_postgresql_unpriv_user; +DROP ROLE cartodb_postgresql_unpriv_user; DROP FUNCTION _CDB_UserQuotaInBytes(); diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 9933008..2be7918 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -27,8 +27,7 @@ BEGIN END; $$ LANGUAGE PLPGSQL; - --- 2) Drop cartodb triggers (might prevent changing columns) +-- Drop cartodb triggers (might prevent changing columns) CREATE OR REPLACE FUNCTION _CDB_drop_triggers(reloid REGCLASS) RETURNS void AS $$ @@ -36,27 +35,23 @@ DECLARE sql TEXT; BEGIN -- "track_updates" - sql := 'DROP TRIGGER IF EXISTS track_updates ON ' || reloid::text; + sql := Format('DROP TRIGGER IF EXISTS track_updates ON %s', 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; + sql := Format('DROP TRIGGER IF EXISTS update_the_geom_webmercator_trigger ON %s', reloid::text); EXECUTE sql; -- "test_quota" and "test_quota_per_row" - sql := 'DROP TRIGGER IF EXISTS test_quota ON ' || reloid::text; + sql := Format('DROP TRIGGER IF EXISTS test_quota ON %s', reloid::text); EXECUTE sql; - sql := 'DROP TRIGGER IF EXISTS test_quota_per_row ON ' || reloid::text; + sql := Format('DROP TRIGGER IF EXISTS test_quota_per_row ON %s', reloid::text); EXECUTE sql; END; $$ LANGUAGE PLPGSQL; --- 3) Cartodb_id creation & validation or renaming if invalid +-- Cartodb_id creation & validation or renaming if invalid CREATE OR REPLACE FUNCTION _CDB_create_cartodb_id_column(reloid REGCLASS) RETURNS void AS $$ @@ -73,7 +68,7 @@ BEGIN LOOP --{ had_column := FALSE; BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' ADD cartodb_id SERIAL NOT NULL UNIQUE'; + sql := Format('ALTER TABLE %s ADD cartodb_id SERIAL NOT NULL UNIQUE', reloid::text); RAISE DEBUG 'Running %', sql; EXECUTE sql; cartodb_id_name := 'cartodb_id'; @@ -103,7 +98,7 @@ BEGIN 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'; + sql := Format('ALTER TABLE %s ALTER COLUMN cartodb_id SET NOT NULL', reloid::text); 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 @@ -132,7 +127,7 @@ BEGIN LOOP --{ new_name := '_cartodb_id' || i; BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN cartodb_id TO ' || new_name; + sql := Format('ALTER TABLE %s RENAME COLUMN cartodb_id TO %I', reloid::text, new_name); RAISE DEBUG 'Running %', sql; EXECUTE sql; EXCEPTION @@ -156,14 +151,12 @@ 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'; + sql := Format('ALTER TABLE %s ALTER cartodb_id TYPE int USING %I', reloid::text, new_name); RAISE DEBUG 'Running %', sql; EXECUTE sql; -- Find max value - sql := 'SELECT max(cartodb_id) FROM ' || reloid::text; + sql := Format('SELECT max(cartodb_id) FROM %s', reloid::text); RAISE DEBUG 'Running %', sql; EXECUTE sql INTO rec; @@ -172,13 +165,12 @@ BEGIN AS seq INTO rec2; -- Reset sequence name - sql := 'ALTER SEQUENCE ' || rec2.seq::text - || ' RESTART WITH ' || rec.max + 1; + sql := Format('ALTER SEQUENCE %s RESTART WITH %d', rec2.seq::text, 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; + sql := Format('ALTER TABLE %s DROP %I', reloid::text, new_name); RAISE DEBUG 'Running %', sql; EXECUTE sql; @@ -194,7 +186,7 @@ BEGIN RAISE EXCEPTION 'Cartodbfying % (Didnt get cartodb_id field name)', reloid; END IF; BEGIN - sql := 'ALTER TABLE ' || reloid::text || ' ADD PRIMARY KEY (cartodb_id)'; + sql := Format('ALTER TABLE %s ADD PRIMARY KEY (cartodb_id)', reloid::text); EXECUTE sql; EXCEPTION WHEN others THEN @@ -205,268 +197,7 @@ 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) - 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; - - --- 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 - 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 || ')'; - RAISE DEBUG 'Running %', sql; - EXECUTE sql; - sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')'; - RAISE DEBUG 'Running %', sql; - 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; - 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 - INTO STRICT rec2; - - IF rec2.typname NOT IN ('geometry') THEN -- { - RAISE NOTICE 'Existing % field is of invalid type % (need geometry), renaming', rec.cname, rec2.typname; - EXIT column_fixup; -- cannot fix - 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; - 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 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 - 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' ) - 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; - END; - END IF; -- } - - -- if we reached this line, all went good - EXIT column_setup; - END LOOP; -- } column_fixup - - -- 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 % (rename %): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE; - END; - EXIT rename_column; - END LOOP; --} - CONTINUE column_setup; - END LOOP; -- } column_setup - END LOOP; -- } on expected geometry columns - - RETURN exists_geom_cols; -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.a) Create all triggers +-- 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 @@ -487,13 +218,6 @@ BEGIN || ' 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 ' @@ -526,13 +250,6 @@ BEGIN || ' 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 ' @@ -563,14 +280,6 @@ BEGIN 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; - -- Auxiliary function CREATE OR REPLACE FUNCTION cartodb._CDB_is_raster_table(schema_name TEXT, reloid REGCLASS) @@ -609,43 +318,877 @@ $$ LANGUAGE PLPGSQL; -- //////////////////////////////////////////////////// -- 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 + +DROP FUNCTION IF EXISTS CDB_CartodbfyTable(reloid REGCLASS); +CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(reloid REGCLASS) +RETURNS REGCLASS AS $$ -DECLARE - exists_geom_cols BOOLEAN[]; - is_raster 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_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; - - -- 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; - + RETURN cartodb.CDB_CartodbfyTable('public', reloid); END; $$ LANGUAGE PLPGSQL; -CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(reloid REGCLASS) + +-- -=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-= +-- +-- NEW CARTODBFY CODE FROM HERE ON DOWN +-- +-- -=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-= +-- +-- CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS) +-- +-- Main function, calls the following functions, with a little +-- logic before the table re-write to avoid re-writing if the table +-- already has all the necessary columns in place. +-- +-- It returns the destoid of the table. If no rewritting is needed +-- the return value will be equal to reloid. +-- +-- +-- (0) _CDB_check_prerequisites +-- As before, this checks the prerequisites before trying to cartodbfy +-- +-- (1) _CDB_drop_triggers +-- As before, this drops all the metadata and geom sync triggers +-- +-- (2) _CDB_Has_Usable_Primary_ID() +-- Returns TRUE if it can find a unique integer primary key named +-- 'cartodb_id' or can rename an existing key. +-- Returns FALSE otherwise. +-- +-- (3) _CDB_Has_Usable_Geom() +-- Looks for existing EPSG:4326 and EPSG:3857 geometry columns, and +-- renames them to the standard names if it can find them, returning TRUE. +-- If it cannot find both columns in the right EPSG, returns FALSE. +-- +-- (4) _CDB_Rewrite_Table() +-- If table does not have a usable primary key and both usable geom +-- columns it needs to be re-written. Function constructs an appropriate +-- CREATE TABLE AS SELECT... query and executes it. +-- +-- (5) _CDB_Add_Indexes() +-- Checks the primary key column for primary key constraint, adds it if +-- missing. Check geometry columns for GIST indexes and adds them if missing. +-- +-- (6) _CDB_create_triggers() +-- Adds the system metadata and geometry column update triggers back +-- onto the table. +-- +-- -=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-=-= + + +CREATE OR REPLACE FUNCTION _CDB_Columns(OUT pkey TEXT, OUT geomcol TEXT, OUT mercgeomcol TEXT) +RETURNS record +AS $$ +BEGIN + +pkey := 'cartodb_id'; +geomcol := 'the_geom'; +mercgeomcol := 'the_geom_webmercator'; + +END; +$$ LANGUAGE 'plpgsql'; + + +CREATE OR REPLACE FUNCTION _CDB_Error(message TEXT, funcname TEXT DEFAULT '_CDB_Error') RETURNS void AS $$ BEGIN - PERFORM cartodb.CDB_CartodbfyTable('public', reloid); + + RAISE EXCEPTION 'CDB(%): %', funcname, message; + END; -$$ LANGUAGE PLPGSQL; +$$ LANGUAGE 'plpgsql'; + + +CREATE OR REPLACE FUNCTION _CDB_SQL(sql TEXT, funcname TEXT DEFAULT '_CDB_SQL') +RETURNS void +AS $$ +BEGIN + + RAISE DEBUG 'CDB(%): %', funcname, sql; + EXECUTE sql; + + EXCEPTION + WHEN others THEN + RAISE EXCEPTION 'CDB(%:%:%): %', funcname, SQLSTATE, SQLERRM, sql; + +END; +$$ LANGUAGE 'plpgsql'; + + +-- Find a unique relation name in the given schema, starting from the +-- template given. If the template is already unique, just return it; +-- otherwise, append an increasing integer until you find a unique variant. +CREATE OR REPLACE FUNCTION _CDB_Unique_Relation_Name(schemaname TEXT, relationname TEXT) +RETURNS TEXT +AS $$ +DECLARE + rec RECORD; + i INTEGER; + newrelname TEXT; +BEGIN + + i := 0; + newrelname := relationname; + LOOP + + SELECT c.relname, n.nspname + INTO rec + FROM pg_class c + JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.relname = newrelname + AND n.nspname = schemaname; + + IF NOT FOUND THEN + RETURN newrelname; + END IF; + + i := i + 1; + newrelname := relationname || '_' || i; + + IF i > 100 THEN + PERFORM _CDB_Error('looping too far', '_CDB_Unique_Relation_Name'); + END IF; + + END LOOP; + +END; +$$ LANGUAGE 'plpgsql'; + + +-- Find a unique column name in the given relation, starting from the +-- column name given. If the column name is already unique, just return it; +-- otherwise, append an increasing integer until you find a unique variant. +CREATE OR REPLACE FUNCTION _CDB_Unique_Column_Name(reloid REGCLASS, columnname TEXT) +RETURNS TEXT +AS $$ +DECLARE + rec RECORD; + i INTEGER; + newcolname TEXT; +BEGIN + + i := 0; + newcolname := columnname; + LOOP + + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + WHERE NOT a.attisdropped + AND a.attnum > 0 + AND c.oid = reloid + AND a.attname = newcolname; + + IF NOT FOUND THEN + RETURN newcolname; + END IF; + + i := i + 1; + newcolname := columnname || '_' || i; + + IF i > 100 THEN + PERFORM _CDB_Error('looping too far', '_CDB_Unique_Column_Name'); + END IF; + + END LOOP; + +END; +$$ LANGUAGE 'plpgsql'; + + +-- Return the geometry SRID from the column metadata or +-- the geometry of the very first entry in a given column. +CREATE OR REPLACE FUNCTION _CDB_Geometry_SRID(reloid REGCLASS, columnname TEXT) +RETURNS INTEGER +AS $$ +DECLARE + rec RECORD; +BEGIN + + RAISE DEBUG 'CDB(%): %', '_CDB_Geometry_SRID', 'entered function'; + + EXECUTE Format('SELECT ST_SRID(%I) AS srid FROM %s LIMIT 1', columnname, reloid::text) + INTO rec; + + IF FOUND THEN + RETURN rec.srid; + END IF; + + RETURN 0; + +END; +$$ LANGUAGE 'plpgsql'; + + +-- Find out if the table already has a usable primary key +-- If the table has both a usable key and usable geometry +-- we can no-op on the table copy and just ensure that the +-- indexes and triggers are in place +CREATE OR REPLACE FUNCTION _CDB_Has_Usable_Primary_ID(reloid REGCLASS) + RETURNS BOOLEAN +AS $$ +DECLARE + rec RECORD; + const RECORD; + i INTEGER; + sql TEXT; + useable_key BOOLEAN = false; +BEGIN + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', 'entered function'; + + -- Read in the names of the CartoDB columns + const := _CDB_Columns(); + + -- Do we already have a properly named column? + SELECT a.attname, i.indisprimary, i.indisunique, a.attnotnull, a.atttypid + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + WHERE c.oid = reloid + AND NOT a.attisdropped + AND a.attname = const.pkey; + + -- Found something named right... + IF FOUND THEN + + -- And it's an integer column... + IF rec.atttypid IN (20,21,23) THEN + + -- And it's a unique primary key! Done! + IF rec.indisprimary AND rec.indisunique AND rec.attnotnull THEN + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', Format('found good ''%s''', const.pkey); + RETURN true; + + -- Check and see if the column values are unique, + -- if they are, we can use this column... + ELSE + + -- Assume things are OK until proven otherwise... + useable_key := true; + + BEGIN + sql := Format('ALTER TABLE %s ADD CONSTRAINT %s_unique UNIQUE (%s)', reloid::text, const.pkey, const.pkey); + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', sql; + EXECUTE sql; + EXCEPTION + -- Failed unique check... + WHEN unique_violation THEN + RAISE NOTICE 'CDB(_CDB_Has_Usable_Primary_ID): %', Format('column %s is not unique', const.pkey); + useable_key := false; + -- Other fatal error + WHEN others THEN + PERFORM _CDB_Error(sql, '_CDB_Has_Usable_Primary_ID'); + END; + + -- Clean up test constraint + IF useable_key THEN + PERFORM _CDB_SQL(Format('ALTER TABLE %s DROP CONSTRAINT %s_unique', reloid::text, const.pkey)); + + -- Move non-unique column out of the way + ELSE + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', + Format('found non-unique ''%s'', renaming it', const.pkey); + + PERFORM _CDB_SQL( + Format('ALTER TABLE %s RENAME COLUMN %s TO %I', + reloid::text, rec.attname, + _CDB_Unique_Column_Name(reloid, const.pkey)), + '_CDB_Has_Usable_Primary_ID'); + + END IF; + + return useable_key; + + END IF; + + -- It's not an integer column, we have to rename it + ELSE + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', + Format('found non-integer ''%s'', renaming it', const.pkey); + + PERFORM _CDB_SQL( + Format('ALTER TABLE %s RENAME COLUMN %s TO %I', + reloid::text, rec.attname, _CDB_Unique_Column_Name(reloid, const.pkey)), + '_CDB_Has_Usable_Primary_ID'); + + END IF; + + -- There's no column there named pkey + ELSE + + -- Is there another suitable primary key already? + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + WHERE c.oid = reloid AND NOT a.attisdropped + AND i.indisprimary AND i.indisunique AND a.attnotnull AND a.atttypid IN (20,21,23); + + -- Yes! Ok, rename it. + IF FOUND THEN + PERFORM _CDB_SQL(Format('ALTER TABLE %s RENAME COLUMN %s TO %s', reloid::text, rec.attname, const.pkey),'_CDB_Has_Usable_Primary_ID'); + RETURN true; + ELSE + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', + Format('found no useful column for ''%s''', const.pkey); + END IF; + + END IF; + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Primary_ID): %', 'function complete'; + + -- Didn't find re-usable key, so return FALSE + RETURN false; + +END; +$$ LANGUAGE 'plpgsql'; + + +CREATE OR REPLACE FUNCTION _CDB_Has_Usable_Geom(reloid REGCLASS) + RETURNS BOOLEAN +AS $$ +DECLARE + r1 RECORD; + r2 RECORD; + const RECORD; + has_geom BOOLEAN := false; + has_mercgeom BOOLEAN := false; + has_geom_name TEXT; + has_mercgeom_name TEXT; + str TEXT; + sql TEXT; +BEGIN + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', 'entered function'; + + -- Read in the names of the CartoDB columns + const := _CDB_Columns(); + + -- Do we have a column we can use? + FOR r1 IN + SELECT + a.attname, + CASE WHEN t.typname = 'geometry' THEN postgis_typmod_srid(a.atttypmod) ELSE NULL END AS srid, + t.typname, + f.desired_attname, f.desired_srid + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid, + (VALUES (const.geomcol, 4326), (const.mercgeomcol, 3857) ) as f(desired_attname, desired_srid) + WHERE c.oid = reloid + AND a.attnum > 0 + AND NOT a.attisdropped + AND postgis_typmod_srid(a.atttypmod) IN (4326, 3857, 0) + ORDER BY t.oid ASC + LOOP + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('checking column ''%s''', r1.attname); + + -- Name collision: right name but wrong type, rename it! + IF r1.typname != 'geometry' AND r1.attname = r1.desired_attname THEN + str := _CDB_Unique_Column_Name(reloid, r1.attname); + sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %I', reloid::text, r1.attname, str); + PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom'); + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', + Format('%s is the wrong type, renamed to %s', r1.attname, str); + + -- Found a geometry column! + ELSIF r1.typname = 'geometry' THEN + + -- If it's the right SRID, we can use it in place without + -- transforming it! + IF r1.srid = r1.desired_srid OR _CDB_Geometry_SRID(reloid, r1.attname) = r1.desired_srid THEN + + RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('found acceptable ''%s''', r1.attname); + + IF r1.desired_attname = const.geomcol THEN + has_geom := true; + has_geom_name := r1.attname; + ELSIF r1.desired_attname = const.mercgeomcol THEN + has_mercgeom := true; + has_mercgeom_name := r1.attname; + END IF; + + END IF; + + END IF; + + END LOOP; + + -- If geom is the wrong name, just rename it. + IF has_geom AND has_geom_name != const.geomcol THEN + sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %s', reloid::text, has_geom_name, const.geomcol); + PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom'); + END IF; + + -- If mercgeom is the wrong name, just rename it. + IF has_mercgeom AND has_mercgeom_name != const.mercgeomcol THEN + sql := Format('ALTER TABLE %s RENAME COLUMN %s TO %s', reloid::text, has_mercgeom_name, const.mercgeomcol); + PERFORM _CDB_SQL(sql,'_CDB_Has_Usable_Geom'); + END IF; + + -- If table is perfect (no transforms required), return TRUE! + RETURN has_geom AND has_mercgeom; + +END; +$$ LANGUAGE 'plpgsql'; + + +-- Create a copy of the table. Assumes that the "Has usable" functions +-- have already been run, so that if there is a 'cartodb_id' column, it is +-- a "good" one, and the same for the geometry columns. If all the required +-- columns are in place already, it no-ops and just renames the table to +-- the destination if necessary. +CREATE OR REPLACE FUNCTION _CDB_Rewrite_Table(reloid REGCLASS, destschema TEXT DEFAULT NULL) +RETURNS BOOLEAN +AS $$ +DECLARE + + relname TEXT; + relschema TEXT; + + destoid REGCLASS; + destname TEXT; + destseq TEXT; + destseqmax INTEGER; + + salt TEXT := md5(random()::text || now()); + copyname TEXT; + + column_name_sql TEXT; + geom_transform_sql TEXT := NULL; + geom_column_source TEXT := ''; + + rec RECORD; + const RECORD; + sql TEXT; + str TEXT; + table_srid INTEGER; + + has_usable_primary_key BOOLEAN; + has_usable_geoms BOOLEAN; + +BEGIN + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', 'entered function'; + + -- Read CartoDB standard column names in + const := _CDB_Columns(); + + -- Save the raw schema/table names for later + SELECT n.nspname, c.relname, c.relname + INTO STRICT relschema, relname, destname + FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = reloid; + + -- Default the destination to current schema if unspecified + IF destschema IS NULL THEN + destschema := relschema; + END IF; + + -- See if there is a primary key column we need to carry along to the + -- new table. If this is true, it implies there is an indexed + -- primary key of integer type named (by default) cartodb_id + SELECT _CDB_Has_Usable_Primary_ID(reloid) AS has_usable_primary_key + INTO STRICT has_usable_primary_key; + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): has_usable_primary_key %', has_usable_primary_key; + + -- See if the geometry columns we need are already available + -- on the table. If they are, we don't need to do any bulk + -- transformation of the table, we can just ensure proper + -- indexes are in place and apply a rename + SELECT _CDB_Has_Usable_Geom(reloid) AS has_usable_geoms + INTO STRICT has_usable_geoms; + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): has_usable_geoms %', has_usable_geoms; + + -- We can only avoid a rewrite if both the key and + -- geometry are usable + + -- No table re-write is required, BUT a rename is required to + -- a destination schema, so do that now + IF has_usable_primary_key AND has_usable_geoms AND destschema != relschema THEN + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): perfect table needs to be moved to schema (%)', destschema; + PERFORM _CDB_SQL(Format('ALTER TABLE %s SET SCHEMA %I', reloid::text, destschema), '_CDB_Rewrite_Table'); + RETURN true; + + -- Don't move anything, just make sure our destination information is set right + ELSIF has_usable_primary_key AND has_usable_geoms AND destschema = relschema THEN + + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): perfect table in the perfect place'; + RETURN true; + + END IF; + + -- We must rewrite, so here we go... + + + -- Put the primary key sequence in the right schema + -- If the new table is not moving, better ensure the sequence name + -- is unique + destseq := relname || '_' || const.pkey || '_seq'; + destseq := _CDB_Unique_Relation_Name(destschema, destseq); + destseq := Format('%I.%I', destschema, destseq); + PERFORM _CDB_SQL(Format('CREATE SEQUENCE %s', destseq), '_CDB_Rewrite_Table'); + + -- Salt a temporary table name if we are re-writing in place + -- Note copyname is already escaped and safe to use as identifier + IF destschema = relschema THEN + copyname := Format('%I.%I', destschema, Format('%s_%s', destname, salt)); + ELSE + --copyname := destschema || '.' || destname; + copyname := Format('%I.%I', destschema, destname); + END IF; + + -- Start building the SQL! + sql := Format('CREATE TABLE %s AS SELECT ', copyname); + + -- Add cartodb ID! + IF has_usable_primary_key THEN + sql := sql || const.pkey; + ELSE + sql := sql || 'nextval(''' || destseq || ''') AS ' || const.pkey; + END IF; + + -- Add the geometry columns! + IF has_usable_geoms THEN + sql := sql || ',' || const.geomcol || ',' || const.mercgeomcol; + ELSE + + -- This gets complicated: we have to make sure the + -- geometry column we are using can be transformed into + -- geographics, which means it needs to have a valid + -- SRID. + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + WHERE c.oid = reloid + AND t.typname = 'geometry' + AND a.attnum > 0 + AND NOT a.attisdropped + ORDER BY a.attnum + LIMIT 1; + + IF NOT FOUND THEN + -- If there is no geometry column, we continue making a + -- non-spatial table. This is important for folks who want + -- their tables to invalidate the SQL API + -- cache on update/insert/delete. + geom_column_source := ''; + sql := sql || ',NULL::geometry(Geometry,4326) AS ' || const.geomcol; + sql := sql || ',NULL::geometry(Geometry,3857) AS ' || const.mercgeomcol; + ELSE + + -- table_srid = _CDB_Geometry_SRID(reloid, rec.attname); + + EXECUTE Format('SELECT ST_SRID(%s) AS srid FROM %s LIMIT 1', rec.attname, reloid::text) + INTO rec; + + -- The geometry columns weren't in the right projection, + -- so we need to find the first decent geometry column + -- in the table and wrap it in two transforms, one to 4326 + -- and another to 3857. Then remember its name so we can + -- ignore it when we build the list of other columns to + -- add to the output table + SELECT ',ST_Transform(' + || a.attname + || ',4326)::Geometry(' + || postgis_typmod_type(a.atttypmod) + || ', 4326) AS ' + || const.geomcol + || ', ST_Transform(' + || a.attname + || ',3857)::Geometry(' + || postgis_typmod_type(a.atttypmod) + || ', 3857) AS ' + || const.mercgeomcol, + a.attname + INTO geom_transform_sql, geom_column_source + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid, + ( SELECT rec.srid AS srid ) AS srid + -- ( SELECT table_srid AS srid ) AS srid + WHERE c.oid = reloid + AND t.typname = 'geometry' + AND a.attnum > 0 + AND NOT a.attisdropped + AND (postgis_typmod_srid(a.atttypmod) > 0 OR srid.srid > 0) + ORDER BY a.attnum + LIMIT 1; + + IF FOUND THEN + sql := sql || geom_transform_sql; + END IF; + + END IF; + + END IF; + + -- Add now add all the rest of the columns + -- by selecting their names into an array and + -- joining the array with a comma + SELECT + ',' || array_to_string(array_agg(a.attname),',') AS column_name_sql, + Count(*) AS count + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_type t ON a.atttypid = t.oid + WHERE c.oid = reloid + AND a.attnum > 0 + AND a.attname NOT IN (const.geomcol, const.mercgeomcol, const.pkey, geom_column_source) + AND NOT a.attisdropped; + + + -- No non-cartodb columns? Possible, I guess. + IF rec.count = 0 THEN + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', 'found no extra columns'; + column_name_sql := ''; + ELSE + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', Format('found extra columns columns ''%s''', rec.column_name_sql); + column_name_sql := rec.column_name_sql; + END IF; + + -- Add the source table to the SQL + sql := sql || column_name_sql || ' FROM ' || reloid::text; + RAISE DEBUG 'CDB(_CDB_Rewrite_Table): %', sql; + + -- Run it! + PERFORM _CDB_SQL(sql, '_CDB_Rewrite_Table'); + + -- Set up the primary key sequence + -- If we copied the primary key from the original data, we need + -- to set the sequence to the maximum value of that key + IF has_usable_primary_key THEN + + EXECUTE Format('SELECT max(%s) FROM %s', + const.pkey, copyname) + INTO destseqmax; + + IF FOUND AND destseqmax IS NOT NULL THEN + PERFORM _CDB_SQL(Format('SELECT setval(''%s'', %s)', destseq, destseqmax), '_CDB_Rewrite_Table'); + END IF; + + END IF; + + -- Make the primary key use the sequence as its default value + sql := Format('ALTER TABLE %s ALTER COLUMN %s SET DEFAULT nextval(''%s'')', + copyname, const.pkey, destseq); + PERFORM _CDB_SQL(sql, '_CDB_Rewrite_Table'); + + -- Make the sequence owned by the table, so when the table drops, + -- the sequence does too + sql := Format('ALTER SEQUENCE %s OWNED BY %s.%s', destseq, copyname, const.pkey); + PERFORM _CDB_SQL(sql,'_CDB_Rewrite_Table'); + + -- We just made a copy, so we can drop the original now + sql := Format('DROP TABLE %s', reloid::text); + PERFORM _CDB_SQL(sql, '_CDB_Rewrite_Table'); + + -- If the table is being created by a SECURITY DEFINER function + -- make sure the user is set back to the user who is connected + IF current_user != session_user THEN + sql := Format('ALTER TABLE IF EXISTS %s OWNER TO %s', copyname, session_user); + PERFORM _CDB_SQL(sql, '_CDB_Rewrite_Table'); + sql := Format('ALTER SEQUENCE IF EXISTS %s OWNER TO %s', destseq, session_user); + PERFORM _CDB_SQL(sql, '_CDB_Rewrite_Table'); + END IF; + + -- If we used a temporary destination table + -- we can now rename it into place + IF destschema = relschema THEN + sql := Format('ALTER TABLE %s RENAME TO %I', copyname, destname); + PERFORM _CDB_SQL(sql, '_CDB_Rewrite_Table'); + END IF; + + RETURN true; + +END; +$$ LANGUAGE 'plpgsql'; + + +-- Assumes the table already has the right metadata columns +-- (primary key and two geometry columns) and adds primary key +-- and geometry indexes if necessary. +CREATE OR REPLACE FUNCTION _CDB_Add_Indexes(reloid REGCLASS) + RETURNS BOOLEAN +AS $$ +DECLARE + rec RECORD; + const RECORD; + iname TEXT; + sql TEXT; + relname TEXT; +BEGIN + + RAISE DEBUG 'CDB(_CDB_Add_Indexes): %', 'entered function'; + + -- Read CartoDB standard column names in + const := _CDB_Columns(); + + -- Extract just the relname to use for the index names + SELECT c.relname + INTO STRICT relname + FROM pg_class c + WHERE c.oid = reloid; + + -- Is there already a primary key on this table for + -- a column other than our chosen primary key? + SELECT ci.relname AS pkey + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + JOIN pg_class ci ON i.indexrelid = ci.oid + WHERE c.oid = reloid + AND NOT a.attisdropped + AND a.attname != const.pkey + AND i.indisprimary; + + -- Yes? Then drop it, we're adding our own PK to the column + -- we prefer. + IF FOUND THEN + RAISE DEBUG 'CDB(_CDB_Add_Indexes): dropping unwanted primary key ''%''', rec.pkey; + sql := Format('ALTER TABLE %s DROP CONSTRAINT IF EXISTS %s', reloid::text, rec.pkey); + PERFORM _CDB_SQL(sql, '_CDB_Add_Indexes'); + END IF; + + + -- Is the default primary key flagged as primary? + SELECT a.attname + INTO rec + FROM pg_class c + JOIN pg_attribute a ON a.attrelid = c.oid + JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + JOIN pg_class ci ON ci.oid = i.indexrelid + WHERE attnum > 0 + AND c.oid = reloid + AND a.attname = const.pkey + AND i.indisprimary + AND i.indisunique + AND NOT attisdropped; + + -- No primary key? Add one. + IF NOT FOUND THEN + sql := Format('ALTER TABLE %s ADD PRIMARY KEY (%s)', reloid::text, const.pkey); + PERFORM _CDB_SQL(sql, '_CDB_Add_Indexes'); + END IF; + + -- Add geometry indexes to all "special geometry columns" that + -- don't have one (either have no index at all, or have a non-GIST index) + FOR rec IN + SELECT a.attname, n.nspname + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + JOIN pg_attribute a ON a.attrelid = c.oid AND attnum > 0 + LEFT JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + WHERE NOT attisdropped + AND a.attname IN (const.geomcol, const.mercgeomcol) + AND c.oid = reloid + AND i.indexrelid IS NULL + UNION + SELECT a.attname, n.nspname + FROM pg_class c + JOIN pg_namespace n ON n.oid = c.relnamespace + JOIN pg_attribute a ON a.attrelid = c.oid AND attnum > 0 + JOIN pg_index i ON c.oid = i.indrelid AND a.attnum = ANY(i.indkey) + JOIN pg_class ci ON ci.oid = i.indexrelid + JOIN pg_am am ON ci.relam = am.oid + WHERE NOT attisdropped + AND a.attname IN (const.geomcol, const.mercgeomcol) + AND c.oid = reloid + AND am.amname != 'gist' + LOOP + sql := Format('CREATE INDEX %s_%s_gix ON %s USING GIST (%s)', relname, rec.attname, reloid::text, rec.attname); + PERFORM _CDB_SQL(sql, '_CDB_Add_Indexes'); + END LOOP; + + RETURN true; + +END; +$$ LANGUAGE 'plpgsql'; + +DROP FUNCTION IF EXISTS CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS); +CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(destschema TEXT, reloid REGCLASS) +RETURNS REGCLASS +AS $$ +DECLARE + + is_raster BOOLEAN; + relname TEXT; + relschema TEXT; + + destoid REGCLASS; + destname TEXT; + + rec RECORD; + +BEGIN + + -- Save the raw schema/table names for later + SELECT n.nspname, c.relname, c.relname + INTO STRICT relschema, relname, destname + FROM pg_class c JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = reloid; + + PERFORM cartodb._CDB_check_prerequisites(destschema, reloid); + + -- Check destination schema exists + -- Throws an exception of there is no matching schema + IF destschema IS NOT NULL THEN + + SELECT n.nspname + INTO rec FROM pg_namespace n WHERE n.nspname = destschema; + IF NOT FOUND THEN + RAISE EXCEPTION 'Schema ''%'' does not exist', destschema; + END IF; + + ELSE + destschema := relschema; + END IF; + + -- Drop triggers first + PERFORM _CDB_drop_triggers(reloid); + + -- Rasters only get a cartodb_id and a limited selection of triggers + -- underlying assumption is that they are already formed up correctly + SELECT cartodb._CDB_is_raster_table(destschema, reloid) INTO is_raster; + IF is_raster THEN + + PERFORM cartodb._CDB_create_cartodb_id_column(reloid); + PERFORM cartodb._CDB_create_raster_triggers(destschema, reloid); + + ELSE + + -- Rewrite (or rename) the table to the new location + PERFORM _CDB_Rewrite_Table(reloid, destschema); + + -- The old regclass might not be valid anymore if we re-wrote the table... + destoid := (destschema || '.' || destname)::regclass; + + -- Add indexes to the destination table, as necessary + PERFORM _CDB_Add_Indexes(destoid); + + -- Add triggers to the destination table, as necessary + PERFORM _CDB_create_triggers(destschema, destoid); + + END IF; + + RETURN (destschema || '.' || destname)::regclass; +END; +$$ LANGUAGE 'plpgsql'; diff --git a/scripts-available/CDB_DDLTriggers.sql b/scripts-available/CDB_DDLTriggers.sql index 81db820..dddd60e 100644 --- a/scripts-available/CDB_DDLTriggers.sql +++ b/scripts-available/CDB_DDLTriggers.sql @@ -4,17 +4,23 @@ CREATE OR REPLACE FUNCTION cartodb.cdb_handle_create_table () RETURNS event_trigger SECURITY DEFINER LANGUAGE plpgsql AS $$ DECLARE event_info RECORD; - rel_namespace TEXT; + rel RECORD; + newtable REGCLASS; BEGIN event_info := schema_triggers.get_relation_create_eventinfo(); -- We're only interested in real relations IF (event_info.new).relkind != 'r' THEN RETURN; END IF; - SELECT nspname FROM pg_namespace WHERE oid=(event_info.new).relnamespace INTO rel_namespace; + SELECT c.relname, c.relnamespace, c.relkind, n.nspname + FROM pg_class c + JOIN pg_namespace n + ON c.relnamespace = n.oid + WHERE c.oid = event_info.relation + INTO rel; RAISE DEBUG 'Relation % of kind % created in table % namespace % (oid %)', - event_info.relation, (event_info.new).relkind, (event_info.new).relname::TEXT, rel_namespace, (event_info.new).relnamespace; + event_info.relation, rel.relkind, rel.relname, rel.nspname, rel.relnamespace; -- We don't want to react to alters triggered by superuser, IF current_setting('is_superuser') = 'on' THEN @@ -25,15 +31,15 @@ BEGIN PERFORM cartodb.cdb_disable_ddl_hooks(); -- CDB_CartodbfyTable must not create tables, or infinite loop will happen - PERFORM cartodb.CDB_CartodbfyTable(rel_namespace, event_info.relation); + newtable := cartodb.CDB_CartodbfyTable(rel.nspname, event_info.relation); PERFORM cartodb.cdb_enable_ddl_hooks(); RAISE DEBUG 'Inserting into cartodb.CDB_TableMetadata'; -- Add entry to CDB_TableMetadata (should CartodbfyTable do this?) - INSERT INTO cartodb.CDB_TableMetadata(tabname,updated_at) - VALUES (event_info.relation, now()); + INSERT INTO cartodb.CDB_TableMetadata(tabname, updated_at) + VALUES (newtable, now()); END; $$; -- } @@ -66,14 +72,19 @@ RETURNS event_trigger SECURITY DEFINER LANGUAGE plpgsql AS $$ DECLARE event_info RECORD; rel RECORD; - rel_namespace TEXT; + newtable REGCLASS; BEGIN event_info := schema_triggers.get_column_alter_eventinfo(); - SELECT oid,* FROM pg_class WHERE oid = event_info.relation INTO rel; + SELECT c.relname, c.relnamespace, c.relkind, n.nspname + FROM pg_class c + JOIN pg_namespace n + ON c.relnamespace = n.oid + WHERE c.oid = event_info.relation + INTO rel; RAISE DEBUG 'Column % altered by % (superuser? %) in relation % of kind %', - (event_info.old).attname, current_user, current_setting('is_superuser'), event_info.relation::regclass, rel.relkind; + (event_info.old).attname, current_user, current_setting('is_superuser'), rel.relname, rel.relkind; -- We're only interested in real relations IF rel.relkind != 'r' THEN RETURN; END IF; @@ -84,16 +95,14 @@ BEGIN RETURN; END IF; - SELECT nspname FROM pg_namespace WHERE oid = rel.relnamespace INTO rel_namespace; - PERFORM cartodb.cdb_disable_ddl_hooks(); - PERFORM cartodb.CDB_CartodbfyTable(rel_namespace, event_info.relation); + newtable := cartodb.CDB_CartodbfyTable(rel.nspname, event_info.relation); PERFORM cartodb.cdb_enable_ddl_hooks(); -- update CDB_TableMetadata.updated_at (should invalidate varnish) - UPDATE cartodb.CDB_TableMetadata SET updated_at = NOW() + UPDATE cartodb.CDB_TableMetadata SET updated_at = NOW(), tabname = newtable WHERE tabname = event_info.relation; END; $$; @@ -106,14 +115,19 @@ RETURNS event_trigger SECURITY DEFINER LANGUAGE plpgsql AS $$ DECLARE event_info RECORD; rel RECORD; - rel_namespace TEXT; + newtable REGCLASS; BEGIN event_info := schema_triggers.get_column_drop_eventinfo(); - SELECT oid,* FROM pg_class WHERE oid = event_info.relation INTO rel; + SELECT c.relname, c.relnamespace, c.relkind, n.nspname + FROM pg_class c + JOIN pg_namespace n + ON c.relnamespace = n.oid + WHERE c.oid = event_info.relation + INTO rel; RAISE DEBUG 'Column % drop by % (superuser? %) in relation % of kind %', - (event_info.old).attname, current_user, current_setting('is_superuser'), event_info.relation::regclass, rel.relkind; + (event_info.old).attname, current_user, current_setting('is_superuser'), rel.relname, rel.relkind; -- We're only interested in real relations IF rel.relkind != 'r' THEN RETURN; END IF; @@ -124,17 +138,16 @@ BEGIN RETURN; END IF; - SELECT nspname FROM pg_namespace WHERE oid = rel.relnamespace INTO rel_namespace; PERFORM cartodb.cdb_disable_ddl_hooks(); - PERFORM cartodb.CDB_CartodbfyTable(rel_namespace, event_info.relation); + newtable := cartodb.CDB_CartodbfyTable(rel.nspname, event_info.relation); PERFORM cartodb.cdb_enable_ddl_hooks(); -- update CDB_TableMetadata.updated_at (should invalidate varnish) - UPDATE cartodb.CDB_TableMetadata SET updated_at = NOW() - WHERE tabname = event_info.relation; + UPDATE cartodb.CDB_TableMetadata SET updated_at = NOW(), tabname = newtable + WHERE tabname = event_info.relation; END; $$; -- } @@ -149,10 +162,15 @@ DECLARE BEGIN event_info := schema_triggers.get_column_add_eventinfo(); - SELECT oid,* FROM pg_class WHERE oid = event_info.relation INTO rel; + SELECT c.relname, c.relnamespace, c.relkind, n.nspname + FROM pg_class c + JOIN pg_namespace n + ON c.relnamespace = n.oid + WHERE c.oid = event_info.relation + INTO rel; RAISE DEBUG 'Column % added by % (superuser? %) in relation % of kind %', - (event_info.new).attname, current_user, current_setting('is_superuser'), event_info.relation::regclass, rel.relkind; + (event_info.new).attname, current_user, current_setting('is_superuser'), rel.relname, rel.relkind; -- We're only interested in real relations IF rel.relkind != 'r' THEN RETURN; END IF; diff --git a/sql/test_ddl_triggers.sql b/sql/test_ddl_triggers.sql index df5c3a4..6ed0d41 100644 --- a/sql/test_ddl_triggers.sql +++ b/sql/test_ddl_triggers.sql @@ -10,6 +10,7 @@ create schema c; SELECT CDB_SetUserQuotaInBytes('c', 0); +DROP USER IF EXISTS cartodb_postgresql_unpriv_user; CREATE USER cartodb_postgresql_unpriv_user; GRANT ALL ON SCHEMA c to cartodb_postgresql_unpriv_user; SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; @@ -21,13 +22,6 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; select 1 as i INTO c.t3; -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i -from c.t3; - RESET SESSION AUTHORIZATION; select tabname::text, @@ -38,11 +32,6 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; -- Table with cartodb_id field, see -- http://github.com/CartoDB/cartodb-postgresql/issues/32 select 1 as cartodb_id INTO c.t4; -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator -from c.t4; RESET SESSION AUTHORIZATION; select @@ -58,13 +47,6 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; select pg_sleep(.1); alter table c.t3 rename column the_geom_webmercator to webmerc; -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc -from c.t3; - RESET SESSION AUTHORIZATION; select tabname::text, @@ -75,13 +57,6 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; select pg_sleep(.1); alter table c.t3 rename column the_geom_webmercator to webmerc2; -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc, webmerc2 -from c.t3; - RESET SESSION AUTHORIZATION; select tabname::text, @@ -95,13 +70,6 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; select pg_sleep(.1); alter table c.t3 drop column the_geom_webmercator; -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc, webmerc2 -from c.t3; - RESET SESSION AUTHORIZATION; select tabname::text, @@ -115,13 +83,6 @@ SET SESSION AUTHORIZATION 'cartodb_postgresql_unpriv_user'; select pg_sleep(.1); alter table c.t3 add column id2 int; -select - cartodb_id, created_at=updated_at as "c=u", - NOW() - updated_at < '1 secs' as "u<1s", - the_geom, the_geom_webmercator, - i, webmerc, webmerc2, id2 -from c.t3; - RESET SESSION AUTHORIZATION; select tabname::text, @@ -136,5 +97,6 @@ RESET SESSION AUTHORIZATION; drop schema c cascade; select count(*) from CDB_TableMetadata; -DROP USER cartodb_postgresql_unpriv_user; +DROP OWNED BY cartodb_postgresql_unpriv_user; +DROP ROLE cartodb_postgresql_unpriv_user; DROP FUNCTION _CDB_UserQuotaInBytes(); diff --git a/sql/test_setup.sql b/sql/test_setup.sql index c05769f..67fe684 100644 --- a/sql/test_setup.sql +++ b/sql/test_setup.sql @@ -7,4 +7,4 @@ RETURNS void AS $$ BEGIN RAISE NOTICE 'cdb_invalidate_varnish(%) called', table_name; END; -$$ LANGUAGE 'plpgsql'; +$$ LANGUAGE 'plpgsql'; \ No newline at end of file diff --git a/test/CDB_CartodbfyTableTest.sql b/test/CDB_CartodbfyTableTest.sql index 3736e80..3204446 100644 --- a/test/CDB_CartodbfyTableTest.sql +++ b/test/CDB_CartodbfyTableTest.sql @@ -12,6 +12,7 @@ DECLARE tmp INTEGER; ogc_geom geometry_columns; -- old the_geom record in geometry_columns ogc_merc geometry_columns; -- old the_geom_webmercator record in geometry_columns + tabtext TEXT; BEGIN -- Save current constraints on geometry columns, if any @@ -30,24 +31,17 @@ BEGIN END IF; END LOOP; + tabtext := Format('%s.%s','public',tabname); + RAISE NOTICE 'CARTODBFYING % !!!!', tabtext; PERFORM CDB_CartodbfyTable('public', tabname); + tabname := tabtext::regclass; sql := 'INSERT INTO ' || tabname::text || '(the_geom) values ( CDB_LatLng(2,1) ) RETURNING cartodb_id'; EXECUTE sql INTO STRICT id; - sql := 'SELECT created_at,updated_at,the_geom_webmercator FROM ' + sql := 'SELECT the_geom_webmercator FROM ' || tabname::text || ' WHERE cartodb_id = ' || id; EXECUTE sql INTO STRICT rec; - -- Check created_at and updated_at at creation time - lag = rec.created_at - now(); - IF lag > '1 second' THEN - RAISE EXCEPTION 'created_at not defaulting to now() after insert [ valued % ago ]', lag; - END IF; - lag = rec.updated_at - now(); - IF lag > '1 second' THEN - RAISE EXCEPTION 'updated_at not defaulting to now() after insert [ valued % ago ]', lag; - END IF; - -- Check the_geom_webmercator trigger IF round(st_x(rec.the_geom_webmercator)) != 111319 THEN RAISE EXCEPTION 'the_geom_webmercator X is % (expecting 111319)', round(st_x(rec.the_geom_webmercator)); @@ -84,7 +78,7 @@ BEGIN rec.f_geometry_column, rec.srid, rec.expsrid; END IF; -- Check TYPE constraint didn't change - IF rec.type != rec.exptype THEN + IF (rec.type != 'GEOMETRY') AND (rec.type != 'POINT') THEN RAISE EXCEPTION 'type of % in geometry_columns is %, expected %', rec.f_geometry_column, rec.type, rec.exptype; END IF; @@ -115,10 +109,10 @@ BEGIN -- Check null constraint on cartodb_id, created_at, updated_at SELECT count(*) FROM pg_attribute a, pg_class c WHERE c.oid = tabname::oid AND a.attrelid = c.oid AND NOT a.attisdropped AND a.attname in - ( 'cartodb_id', 'created_at', 'updated_at' ) + ( 'cartodb_id' ) AND NOT a.attnotnull INTO strict tmp; IF tmp > 0 THEN - RAISE EXCEPTION 'cartodb_id or created_at or updated_at are missing not-null constraint'; + RAISE EXCEPTION 'cartodb_id is missing not-null constraint'; END IF; -- Cleanup @@ -170,29 +164,19 @@ SELECT CDB_CartodbfyTableCheck('t', 'trigger-protected the_geom'); SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)) FROM t; DROP TABLE t; --- table with existing updated_at and created_at fields ot type text -CREATE TABLE t AS SELECT NOW()::text as created_at, - NOW()::text as updated_at, - NOW() as reftime; -SELECT CDB_CartodbfyTableCheck('t', 'text timestamps'); -SELECT extract(secs from reftime-created_at), - extract(secs from reftime-updated_at) FROM t; -CREATE VIEW v AS SELECT * FROM t; -SELECT CDB_CartodbfyTableCheck('t', 'cartodbfied with view'); -DROP VIEW v; -DROP TABLE t; +-- INFO: disabled because cartodbfy does not longer consider text columns for primary ID +-- -- table with existing cartodb_id field of type text +-- CREATE TABLE t AS SELECT 10::text as cartodb_id; +-- SELECT CDB_CartodbfyTableCheck('t', 'text cartodb_id'); +-- select cartodb_id/2 FROM t; +-- DROP TABLE t; --- table with existing cartodb_id field of type text -CREATE TABLE t AS SELECT 10::text as cartodb_id; -SELECT CDB_CartodbfyTableCheck('t', 'text cartodb_id'); -select cartodb_id/2 FROM t; -DROP TABLE t; - --- table with existing cartodb_id field of type text not casting -CREATE TABLE t AS SELECT 'nan' as cartodb_id; -SELECT CDB_CartodbfyTableCheck('t', 'uncasting text cartodb_id'); -select cartodb_id,_cartodb_id0 FROM t; -DROP TABLE t; +-- INFO: disabled because cartodbfy does not longer consider text columns for primary ID +-- -- table with existing cartodb_id field of type text not casting +-- CREATE TABLE t AS SELECT 'nan' as cartodb_id; +-- SELECT CDB_CartodbfyTableCheck('t', 'uncasting text cartodb_id'); +-- select cartodb_id,_cartodb_id0 FROM t; +-- DROP TABLE t; -- table with existing cartodb_id field of type int4 not sequenced CREATE TABLE t AS SELECT 1::int4 as cartodb_id; @@ -208,22 +192,6 @@ WHERE c.conrelid = 't'::regclass and a.attrelid = c.conrelid AND c.conkey[1] = a.attnum AND NOT a.attisdropped; DROP TABLE t; --- table with existing the_geom and created_at and containing null values --- Really, a test for surviving an longstanding PostgreSQL bug: --- http://www.postgresql.org/message-id/20140530143150.GA11051@localhost -CREATE TABLE t ( - the_geom geometry(Geometry,4326), - created_at timestamptz, - updated_at timestamptz -); -COPY t (the_geom, created_at, updated_at) FROM stdin; -0106000020E610000001000000010300000001000000050000009EB8244146435BC017B65E062AD343409EB8244146435BC0F51AF6E2708044400B99891683765AC0F51AF6E2708044400B99891683765AC017B65E062AD343409EB8244146435BC017B65E062AD34340 2012-06-06 21:59:08 2013-06-10 20:17:20 -0106000020E61000000100000001030000000100000005000000DA7763431A1A5CC0FBCEE869313C3A40DA7763431A1A5CC09C1B8F55BC494440F9F4A9C7993356C09C1B8F55BC494440F9F4A9C7993356C0FBCEE869313C3A40DA7763431A1A5CC0FBCEE869313C3A40 2012-06-06 21:59:08 2013-06-10 20:17:20 -\N \N \N -\. -SELECT CDB_CartodbfyTableCheck('t', 'null geom and timestamp values'); -DROP TABLE t; - -- TODO: table with existing custom-triggered the_geom DROP FUNCTION CDB_CartodbfyTableCheck(regclass, text); diff --git a/test/CDB_CartodbfyTableTest_expect b/test/CDB_CartodbfyTableTest_expect index 5a3b090..2839fde 100644 --- a/test/CDB_CartodbfyTableTest_expect +++ b/test/CDB_CartodbfyTableTest_expect @@ -2,8 +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 7 at PERFORM +CONTEXT: SQL statement "SELECT cartodb._CDB_check_prerequisites(destschema, reloid)" +PL/pgSQL function cdb_cartodbfytable(text,regclass) line 21 at PERFORM 0 single non-geometrical column cartodbfied fine DROP TABLE @@ -28,21 +28,6 @@ trigger-protected the_geom cartodbfied fine extent|BOX(1 1,2 2) DROP TABLE SELECT 1 -text timestamps cartodbfied fine -0|0 -CREATE VIEW -cartodbfied with view cartodbfied fine -DROP VIEW -DROP TABLE -SELECT 1 -text cartodb_id cartodbfied fine -5 -DROP TABLE -SELECT 1 -uncasting text cartodb_id cartodbfied fine -1|nan -DROP TABLE -SELECT 1 unsequenced cartodb_id cartodbfied fine 1 DROP TABLE @@ -50,8 +35,5 @@ CREATE TABLE cartodb_id serial primary key cartodbfied fine t_pkey|cartodb_id DROP TABLE -CREATE TABLE -null geom and timestamp values cartodbfied fine -DROP TABLE DROP FUNCTION DROP FUNCTION diff --git a/test/CDB_QuotaTest.sql b/test/CDB_QuotaTest.sql index 69cd84b..f834c7b 100644 --- a/test/CDB_QuotaTest.sql +++ b/test/CDB_QuotaTest.sql @@ -7,21 +7,21 @@ CREATE TABLE big(a int); CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON big EXECUTE PROCEDURE CDB_CheckQuota(1, 1, 'public'); INSERT INTO big VALUES (1); -- allowed, check runs before -INSERT INTO big VALUES (1); -- disallowed, quota exceeds before +INSERT INTO big VALUES (2); -- disallowed, quota exceeds before SELECT CDB_SetUserQuotaInBytes(0); SELECT CDB_CartodbfyTable('big'); -INSERT INTO big SELECT generate_series(1,2048); -INSERT INTO big SELECT generate_series(1,2048); -INSERT INTO big SELECT generate_series(1,2048); +INSERT INTO big SELECT generate_series(2049,4096); +INSERT INTO big SELECT generate_series(4097,6144); +INSERT INTO big SELECT generate_series(6145,8192); -- Test for #108: https://github.com/CartoDB/cartodb-postgresql/issues/108 SELECT CDB_UserDataSize(); SELECT cartodb._CDB_total_relation_size('public', 'big'); SELECT cartodb._CDB_total_relation_size('public', 'nonexistent_table_name'); -- END Test for #108 SELECT CDB_SetUserQuotaInBytes(2); -INSERT INTO big VALUES (1); +INSERT INTO big VALUES (8193); SELECT CDB_SetUserQuotaInBytes(0); -INSERT INTO big VALUES (1); +INSERT INTO big VALUES (8194); DROP TABLE big; set client_min_messages to NOTICE; DROP FUNCTION _CDB_UserQuotaInBytes(); diff --git a/test/CDB_QuotaTest_expect b/test/CDB_QuotaTest_expect index ebe7156..de50130 100644 --- a/test/CDB_QuotaTest_expect +++ b/test/CDB_QuotaTest_expect @@ -4,15 +4,15 @@ CREATE TRIGGER INSERT 0 1 ERROR: Quota exceeded by 3.9990234375KB 0 - +big INSERT 0 2048 INSERT 0 2048 INSERT 0 2048 -581632 -1163264 +454656 +909312 0 2 -ERROR: Quota exceeded by 567.998046875KB +ERROR: Quota exceeded by 443.998046875KB 0 INSERT 0 1 DROP TABLE