diff --git a/.travis.yml b/.travis.yml index c2a88a6..0113cd4 100644 --- a/.travis.yml +++ b/.travis.yml @@ -6,6 +6,7 @@ addons: before_install: #- sudo apt-get install -q postgresql-9.3-postgis-2.1 - sudo apt-get install -q postgresql-server-dev-9.3 + - sudo apt-get install -q postgresql-plpython-9.3 # Install schema_triggers - hg clone https://bitbucket.org/malloclabs/pg_schema_triggers && cd pg_schema_triggers && make && sudo make install && cd - diff --git a/Makefile b/Makefile index 81be8aa..6e50441 100644 --- a/Makefile +++ b/Makefile @@ -1,19 +1,43 @@ # cartodb/Makefile EXTENSION = cartodb -EXTVERSION = 0.1dev +EXTVERSION = 0.3.0dev + +SED = sed CDBSCRIPTS = \ - scripts-available/CDB_Roles.sql \ scripts-enabled/*.sql \ scripts-available/CDB_SearchPath.sql \ + scripts-available/CDB_DDLTriggers.sql \ + scripts-available/CDB_ExtensionPost.sql \ + scripts-available/CDB_ExtensionUtils.sql \ $(END) +UPGRADABLE = \ + unpackaged \ + 0.1.0 \ + 0.1.1 \ + 0.2.0 \ + 0.2.1 \ + $(EXTVERSION)next \ + $(END) + +UPGRADES = \ + $(shell echo $(UPGRADABLE) | \ + $(SED) 's/^/$(EXTENSION)--/' | \ + $(SED) 's/$$/--$(EXTVERSION).sql/' | \ + $(SED) 's/ /--$(EXTVERSION).sql $(EXTENSION)--/g') + +REV=$(shell git describe) +GITDIR=$(shell test -d .git && echo '.git' || cat .git | $(SED) 's/^gitdir: //') + DATA_built = \ $(EXTENSION)--$(EXTVERSION).sql \ - $(EXTENSION)--unpackaged--$(EXTVERSION).sql \ - $(EXTENSION).control \ - cartodb_version.sql + $(EXTENSION)--$(EXTVERSION)--$(EXTVERSION)next.sql \ + $(UPGRADES) \ + $(EXTENSION).control + +EXTRA_CLEAN = cartodb_version.sql DOCS = README.md REGRESS_NEW = test_ddl_triggers @@ -25,23 +49,28 @@ PG_CONFIG = pg_config PGXS := $(shell $(PG_CONFIG) --pgxs) include $(PGXS) -$(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_hooks.sql cartodb_version.sql Makefile +$(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile echo '\echo Use "CREATE EXTENSION $(EXTENSION)" to load this file. \quit' > $@ cat $(CDBSCRIPTS) | \ - sed -e 's/\> $@ echo "GRANT USAGE ON SCHEMA cartodb TO public;" >> $@ - cat cartodb_hooks.sql >> $@ cat cartodb_version.sql >> $@ $(EXTENSION)--unpackaged--$(EXTVERSION).sql: $(EXTENSION)--$(EXTVERSION).sql util/create_from_unpackaged.sh Makefile ./util/create_from_unpackaged.sh $(EXTVERSION) -$(EXTENSION).control: $(EXTENSION).control.in - sed -e 's/@@VERSION@@/$(EXTVERSION)/' $< > $@ +$(EXTENSION)--%--$(EXTVERSION).sql: $(EXTENSION)--$(EXTVERSION).sql + cp $< $@ -cartodb_version.sql: cartodb_version.sql.in - sed -e 's/@@VERSION@@/$(EXTVERSION)/' $< > $@ +$(EXTENSION)--$(EXTVERSION)--$(EXTVERSION)next.sql: $(EXTENSION)--$(EXTVERSION).sql + cp $< $@ + +$(EXTENSION).control: $(EXTENSION).control.in Makefile + $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' $< > $@ + +cartodb_version.sql: cartodb_version.sql.in Makefile $(GITDIR)/index + $(SED) -e 's/@@VERSION@@/$(EXTVERSION) $(REV)/' $< > $@ legacy_regress: $(REGRESS_OLD) Makefile mkdir -p sql/test/ @@ -55,7 +84,7 @@ legacy_regress: $(REGRESS_OLD) Makefile echo '\\t' >> $${of}; \ echo '\\set QUIET off' >> $${of}; \ cat $${f} | \ - sed -e 's/\> $${of}; \ + $(SED) -e 's/public\./cartodb./g' >> $${of}; \ exp=expected/test/$${tn}.out; \ echo '\\set ECHO off' > $${exp}; \ cat test/$${tn}_expect >> $${exp}; \ diff --git a/NEWS b/NEWS index 2e38bbb..ceb93dc 100644 --- a/NEWS +++ b/NEWS @@ -1,4 +1,51 @@ -0.1 - 2014-MM-DD ----------------- +0.3.0dev - 2014-MM-DD +------------------ + +0.2.1 - 2014-06-11 +------------------ + +Enhancements: + + - Do not force re-cartodbfication on CREATE FROM unpackaged + - Drop useless DEFAULT specification in plpgsql variable declarations + - List plpythonu requirement first, to get pg_catalog scanned before public + +Bug fixes: + + - Do not add unique index on cartodb_id if already a primary key (#38) + +0.2.0 - 2014-06-09 +------------------ + +Important changes: + + - This release adds dependency on "plpythonu" extension + - Roles are not created anymore, previously private functions + for table information extraction (CDB_UserTables, CDB_TableIndexes, + CDB_ColumnNames, CDB_ColumnType) will now be callable by anyone while + only returning information about tables over which the calling user + has SELECT privilege (#36) + +Bug fixes: + + - Fix recursive trigger on create table (#32) + - Ensure cartodb_id uses an associated sequence (#33) + - Fully qualify call to cdb_disable_ddl_hooks from cdb_enable_ddl_hooks + - Fully qualify call to CDB_UserDataSize from quota trigger + - Fully qualify call to CDB_TransformToWebmercator from CDB_CartodbfyTable + - Fix potential infinite loop in CDB_CartodbfyTable + - Fix potential infinite loop in CDB_QueryStatements + +Enhancements: + + - Include revision info in cdb_version() output (#34) + +New features: + + - Add a cdb_extension_reload() function + + +0.1.0 - 2014-05-23 +------------------ Initial release diff --git a/README.md b/README.md index 15086fe..698f16e 100644 --- a/README.md +++ b/README.md @@ -11,9 +11,11 @@ See https://github.com/CartoDB/cartodb/wiki/CartoDB-PostgreSQL-extension Dependencies ------------ - * PostgreSQL 9.3+ + * PostgreSQL 9.3+ (with plpythonu extension) + * [PostGIS extension](http://postgis.net) * [Schema triggers extension] (https://bitbucket.org/malloclabs/pg_schema_triggers) + (or [fork](https://github.com/CartoDB/pg_schema_triggers)) Install ------- @@ -56,3 +58,48 @@ CREATE EXTENSION schema_triggers; CREATE EXTENSION cartodb FROM unpackaged; ``` +Update cartodb extension +------------------------ + +Updating the version of cartodb extension installed in a database +is done using ALTER EXTENSION. + +```sql +ALTER EXTENSION cartodb UPDATE TO '0.1.1'; +``` + +The target version needs to be installed on the system first +(see Install section). + +If the "TO 'x.y.z'" part is omitted, the extension will be updated to the +latest installed version, which you can find with the following command: + +```sh +grep default_version `pg_config --sharedir`/extension/cartodb.control +``` + +Updates are performed by PostgreSQL by loading one or more migration scripts +as needed to go from the installed version S to the target version T. +All migration scripts are in the "extension" directory of PostgreSQL: + +```sh +ls `pg_config --sharedir`/extension/cartodb* +``` + +During development the cartodb extension version doesn't change with +every commit, so testing latest change requires cheating with PostgreSQL +so to enforce re-load of the scripts. To help with cheating, "make install" +also installs migration scripts to go from "V" to "V"next and from "V"next +to "V". Example to upgrade a 0.2.0dev version: + +```sql +ALTER EXTENSION cartodb UPDATE TO '0.2.0devnext'; +ALTER EXTENSION cartodb UPDATE TO '0.2.0dev'; +``` + +Starting with 0.2.0, the in-place reload can be done with an ad-hoc function: + +```sql +SELECT cartodb.cdb_extension_reload(); +``` + diff --git a/cartodb.control.in b/cartodb.control.in index 36fc0ee..c331343 100644 --- a/cartodb.control.in +++ b/cartodb.control.in @@ -3,4 +3,4 @@ comment = 'Turn a database into a cartodb user database.' superuser = true relocatable = false schema = cartodb -requires = 'schema_triggers, postgis' +requires = 'plpythonu, schema_triggers, postgis' diff --git a/expected/test_ddl_triggers.out b/expected/test_ddl_triggers.out index fbbbbb4..dc263a9 100644 --- a/expected/test_ddl_triggers.out +++ b/expected/test_ddl_triggers.out @@ -6,6 +6,18 @@ SELECT CDB_SetUserQuotaInBytes(0); 0 (1 row) +-- Enable ddl triggers +SELECT cartodb.cdb_enable_ddl_hooks(); +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 + cdb_enable_ddl_hooks +---------------------- + +(1 row) + create schema c; CREATE USER cartodb_postgresql_unpriv_user; GRANT ALL ON SCHEMA c to cartodb_postgresql_unpriv_user; @@ -20,6 +32,11 @@ NOTICE: trigger "update_the_geom_webmercator_trigger" for table "c.t3" does not 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 +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", @@ -35,12 +52,48 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)) as age -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; tabname | age ---------+----- c.t3 | 0 (1 row) +-- Table with cartodb_id field, see +-- http://github.com/CartoDB/cartodb-postgresql/issues/32 +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) + +select + tabname::text, + round(extract('secs' from now() - updated_at)) as age +FROM CDB_TableMetadata WHERE tabname = 'c.t4'::regclass; + tabname | age +---------+----- + c.t4 | 0 +(1 row) + ---------------------------- -- ALTER TABLE RENAME COLUMN ---------------------------- @@ -75,7 +128,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; tabname | agecs ---------+------- c.t3 | 0 @@ -112,7 +165,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; tabname | agecs ---------+------- c.t3 | 0 @@ -152,7 +205,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; tabname | agecs ---------+------- c.t3 | 0 @@ -183,7 +236,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; tabname | agecs ---------+------- c.t3 | 0 @@ -194,8 +247,8 @@ FROM CDB_TableMetadata; ---------------------------- RESET SESSION AUTHORIZATION; drop schema c cascade; -NOTICE: drop cascades to table c.t3 -select count(*) from CDB_TableMetadata; +NOTICE: drop cascades to 2 other objects +select count(*) from CDB_TableMetadata; count ------- 0 diff --git a/expected/test_setup.out b/expected/test_setup.out index 1f4bf2a..c05769f 100644 --- a/expected/test_setup.out +++ b/expected/test_setup.out @@ -1,5 +1,6 @@ CREATE EXTENSION postgis; CREATE EXTENSION schema_triggers; +CREATE EXTENSION plpythonu; CREATE EXTENSION cartodb; CREATE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$ diff --git a/scripts-available/CDB_CartodbfyTable.sql b/scripts-available/CDB_CartodbfyTable.sql index 97c754c..ad56404 100644 --- a/scripts-available/CDB_CartodbfyTable.sql +++ b/scripts-available/CDB_CartodbfyTable.sql @@ -10,7 +10,7 @@ CREATE OR REPLACE FUNCTION _CDB_update_the_geom_webmercator() RETURNS trigger AS $$ BEGIN - NEW.the_geom_webmercator := CDB_TransformToWebmercator(NEW.the_geom); + NEW.the_geom_webmercator := public.CDB_TransformToWebmercator(NEW.the_geom); RETURN NEW; END; $$ LANGUAGE plpgsql VOLATILE; @@ -83,18 +83,27 @@ BEGIN RAISE NOTICE 'Column cartodb_id already exists'; had_column := TRUE; WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', + reloid, SQLERRM, SQLSTATE; END; IF had_column THEN + SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') + AS seq INTO rec2; + -- Check data type is an integer - SELECT t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a + SELECT + pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') as seq, + t.typname, t.oid, a.attnotnull FROM pg_type t, pg_attribute a WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = 'cartodb_id' INTO STRICT rec; - IF rec.oid NOT IN (20,21,23) THEN -- int2, int4, int8 { + -- 20=int2, 21=int4, 23=int8 + IF rec.oid NOT IN (20,21,23) THEN -- { RAISE NOTICE 'Existing cartodb_id field is of invalid type % (need int2, int4 or int8), renaming', rec.typname; + ELSIF rec.seq IS NULL THEN -- }{ + RAISE NOTICE 'Existing cartodb_id field does not have an associated sequence, renaming'; ELSE -- }{ sql := 'ALTER TABLE ' || reloid::text || ' ALTER COLUMN cartodb_id SET NOT NULL'; IF NOT EXISTS ( SELECT c.conname FROM pg_constraint c, pg_attribute a @@ -102,7 +111,7 @@ BEGIN AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = 'cartodb_id' - AND c.contype = 'u' ) -- unique + AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey THEN sql := sql || ', ADD unique(cartodb_id)'; END IF; @@ -114,7 +123,8 @@ BEGIN WHEN unique_violation OR not_null_violation THEN RAISE NOTICE '%, renaming', SQLERRM; WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', + reloid, SQLERRM, SQLSTATE; END; END IF; -- } @@ -133,7 +143,8 @@ BEGIN i := i+1; CONTINUE rename_column; WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)', + reloid, SQLERRM, SQLSTATE; END; EXIT rename_column; END LOOP; --} @@ -142,8 +153,51 @@ BEGIN END IF; END LOOP; -- } + -- Try to copy data from new name if possible + IF new_name IS NOT NULL THEN + RAISE NOTICE 'Trying to recover data from % column', new_name; + BEGIN + -- Copy existing values to new field + -- NOTE: using ALTER is a workaround to a PostgreSQL bug and + -- is also known to be faster for tables with many rows + -- See http://www.postgresql.org/message-id/20140530143150.GA11051@localhost + sql := 'ALTER TABLE ' || reloid::text + || ' ALTER cartodb_id TYPE int USING ' + || new_name || '::int4'; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Find max value + sql := 'SELECT max(cartodb_id) FROM ' || reloid::text; + RAISE DEBUG 'Running %', sql; + EXECUTE sql INTO rec; + + -- Find sequence name + SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id') + AS seq INTO rec2; + + -- Reset sequence name + sql := 'ALTER SEQUENCE ' || rec2.seq::text + || ' RESTART WITH ' || rec.max + 1; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + -- Drop old column (all went find if we got here) + sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name; + RAISE DEBUG 'Running %', sql; + EXECUTE sql; + + EXCEPTION + WHEN others THEN + RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)', + SQLERRM, SQLSTATE; + END; + END IF; + -- We need created_at and updated_at - FOR rec IN SELECT * FROM ( VALUES ('created_at'), ('updated_at') ) t(cname) LOOP --{ + FOR rec IN SELECT * FROM ( VALUES ('created_at'), ('updated_at') ) t(cname) + LOOP --{ + new_name := null; << column_setup >> LOOP --{ had_column := FALSE; @@ -158,30 +212,39 @@ BEGIN RAISE NOTICE 'Column % already exists', rec.cname; had_column := TRUE; WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + 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 + 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; + RAISE NOTICE 'Existing % field is of invalid type % (need timestamptz), renaming', rec. +cname, rec2.typname; ELSE -- }{ - sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname - || ' SET NOT NULL, ALTER ' || rec.cname || ' SET DEFAULT now()'; + -- 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 + 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 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (%): % (%)', + reloid, rec.cname, SQLERRM, SQLSTATE; END; END IF; -- } @@ -199,7 +262,8 @@ BEGIN i := i+1; CONTINUE rename_column; WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (renaming %): % (%)', + reloid, rec.cname, SQLERRM, SQLSTATE; END; EXIT rename_column; END LOOP; --} @@ -208,6 +272,32 @@ BEGIN 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; -- } -- We need the_geom and the_geom_webmercator @@ -228,7 +318,8 @@ BEGIN exists_geom_cols := array_append(exists_geom_cols, true); RAISE NOTICE 'Column % already exists', rec.cname; WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (%): % (%)', + reloid, rec.cname, SQLERRM, SQLSTATE; END; << column_fixup >> @@ -280,7 +371,8 @@ BEGIN EXECUTE sql; EXCEPTION WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (% index): % (%)', + reloid, rec.cname, SQLERRM, SQLSTATE; END; END IF; -- } @@ -303,7 +395,8 @@ BEGIN i := i+1; CONTINUE rename_column; WHEN others THEN - RAISE EXCEPTION 'Got % (%)', SQLERRM, SQLSTATE; + RAISE EXCEPTION 'Cartodbfying % (rename %): % (%)', + reloid, rec.cname, SQLERRM, SQLSTATE; END; EXIT rename_column; END LOOP; --} @@ -325,7 +418,7 @@ BEGIN -- do this only if the_geom was found (not created) -- _and_ the_geom_webmercator was NOT found. IF exists_geom_cols[1] AND NOT exists_geom_cols[2] THEN - sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = CDB_TransformToWebmercator(the_geom) '; + sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = public.CDB_TransformToWebmercator(the_geom) '; EXECUTE sql; END IF; diff --git a/scripts-available/CDB_ColumnNames.sql b/scripts-available/CDB_ColumnNames.sql index 2c74dbc..693ba3d 100644 --- a/scripts-available/CDB_ColumnNames.sql +++ b/scripts-available/CDB_ColumnNames.sql @@ -11,6 +11,6 @@ AS $$ $$ LANGUAGE SQL; --- This is a private function, so only the db owner need privileges -REVOKE ALL ON FUNCTION CDB_ColumnNames(REGCLASS) FROM PUBLIC; -GRANT EXECUTE ON FUNCTION CDB_ColumnNames(REGCLASS) TO ":DATABASE_USERNAME"; +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION CDB_ColumnNames(REGCLASS) TO PUBLIC; diff --git a/scripts-available/CDB_ColumnType.sql b/scripts-available/CDB_ColumnType.sql index 6b8196e..f887771 100644 --- a/scripts-available/CDB_ColumnType.sql +++ b/scripts-available/CDB_ColumnType.sql @@ -12,6 +12,6 @@ AS $$ $$ LANGUAGE SQL; --- This is a private function, so only the db owner need privileges -REVOKE ALL ON FUNCTION CDB_ColumnType(REGCLASS, TEXT) FROM PUBLIC; -GRANT EXECUTE ON FUNCTION CDB_ColumnType(REGCLASS, TEXT) TO ":DATABASE_USERNAME"; +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION CDB_ColumnType(REGCLASS, TEXT) TO public; diff --git a/cartodb_hooks.sql b/scripts-available/CDB_DDLTriggers.sql similarity index 96% rename from cartodb_hooks.sql rename to scripts-available/CDB_DDLTriggers.sql index 0950ec2..37ab988 100644 --- a/cartodb_hooks.sql +++ b/scripts-available/CDB_DDLTriggers.sql @@ -1,8 +1,3 @@ ---LOAD 'schema_triggers.so'; ---CREATE EXTENSION IF NOT EXISTS schema_triggers; - ---GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA schema_triggers TO public; - -- Table creation -- { CREATE OR REPLACE FUNCTION cartodb.cdb_handle_create_table () @@ -24,9 +19,13 @@ BEGIN RETURN; END IF; + PERFORM cartodb.cdb_disable_ddl_hooks(); + -- CDB_CartodbfyTable must not create tables, or infinite loop will happen PERFORM cartodb.CDB_CartodbfyTable(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?) @@ -171,7 +170,7 @@ CREATE OR REPLACE FUNCTION cartodb.cdb_disable_ddl_hooks() returns void AS $$ $$ LANGUAGE sql; CREATE OR REPLACE FUNCTION cartodb.cdb_enable_ddl_hooks() returns void AS $$ - SELECT cdb_disable_ddl_hooks(); + SELECT cartodb.cdb_disable_ddl_hooks(); CREATE EVENT TRIGGER cdb_on_relation_create ON "relation_create" EXECUTE PROCEDURE cartodb.cdb_handle_create_table(); CREATE EVENT TRIGGER cdb_on_relation_drop @@ -184,4 +183,5 @@ CREATE OR REPLACE FUNCTION cartodb.cdb_enable_ddl_hooks() returns void AS $$ ON "column_add" EXECUTE PROCEDURE cartodb.cdb_handle_add_column(); $$ LANGUAGE sql; -SELECT cartodb.cdb_enable_ddl_hooks(); +-- Do not enable hooks by default +--SELECT cartodb.cdb_enable_ddl_hooks(); diff --git a/scripts-available/CDB_DateToNumber.sql b/scripts-available/CDB_DateToNumber.sql index c879112..1b9a449 100644 --- a/scripts-available/CDB_DateToNumber.sql +++ b/scripts-available/CDB_DateToNumber.sql @@ -2,7 +2,7 @@ -- CREATE OR REPLACE FUNCTION CDB_DateToNumber(input timestamp) RETURNS double precision AS $$ -DECLARE output double precision DEFAULT NULL; +DECLARE output double precision; BEGIN BEGIN SELECT extract (EPOCH FROM input) INTO output; diff --git a/scripts-available/CDB_ExtensionPost.sql b/scripts-available/CDB_ExtensionPost.sql new file mode 100644 index 0000000..36aa652 --- /dev/null +++ b/scripts-available/CDB_ExtensionPost.sql @@ -0,0 +1,2 @@ +SELECT pg_catalog.pg_extension_config_dump('cartodb.cdb_tablemetadata',''); + diff --git a/scripts-available/CDB_ExtensionUtils.sql b/scripts-available/CDB_ExtensionUtils.sql new file mode 100644 index 0000000..853bd95 --- /dev/null +++ b/scripts-available/CDB_ExtensionUtils.sql @@ -0,0 +1,13 @@ +CREATE OR REPLACE FUNCTION cartodb.cdb_extension_reload() RETURNS void +AS $$ +DECLARE + ver TEXT; + sql TEXT; +BEGIN + ver := split_part(cartodb.cdb_version(), ' ', 1); + sql := 'ALTER EXTENSION cartodb UPDATE TO ''' || ver || 'next'''; + EXECUTE sql; + sql := 'ALTER EXTENSION cartodb UPDATE TO ''' || ver || ''''; + EXECUTE sql; +END; +$$ language 'plpgsql' VOLATILE; diff --git a/scripts-available/CDB_Hexagon.sql b/scripts-available/CDB_Hexagon.sql index 131aa12..7b57a98 100644 --- a/scripts-available/CDB_Hexagon.sql +++ b/scripts-available/CDB_Hexagon.sql @@ -27,7 +27,7 @@ $$ LANGUAGE 'sql' IMMUTABLE STRICT; -- as the extent. -- -- -DROP FUNCTION IF EXISTS CDB_HexagonGrid(ext GEOMETRY, side FLOAT8); +-- DROP FUNCTION IF EXISTS CDB_HexagonGrid(ext GEOMETRY, side FLOAT8); CREATE OR REPLACE FUNCTION CDB_HexagonGrid(ext GEOMETRY, side FLOAT8, origin GEOMETRY DEFAULT NULL) RETURNS SETOF GEOMETRY AS $$ diff --git a/scripts-available/CDB_QueryStatements.sql b/scripts-available/CDB_QueryStatements.sql index 9c8309a..bb4d10c 100644 --- a/scripts-available/CDB_QueryStatements.sql +++ b/scripts-available/CDB_QueryStatements.sql @@ -1,13 +1,14 @@ -- Return an array of statements found in the given query text -- --- Curtesy of Hubert Lubaczewski (depesz) +-- Regexp curtesy of Hubert Lubaczewski (depesz) +-- Implemented in plpython for performance reasons -- CREATE OR REPLACE FUNCTION CDB_QueryStatements(query text) RETURNS SETOF TEXT AS $$ - SELECT stmt FROM ( - SELECT btrim(q[1], E' \n\t\r;') as stmt FROM ( - SELECT regexp_matches( $1, $REG$((?:[^'"$;]+|"[^"]*"|'(?:[^']*|'')*'|(\$[^$]*\$).*?\2)+)$REG$, 'g' ) as q - ) i - ) j - WHERE stmt <> ''; -$$ language sql IMMUTABLE STRICT; + import re + pat = re.compile( r'''((?:[^'"$;]+|"[^"]*"|'[^']*'|(\$[^$]*\$).*?\2)+)''', re.DOTALL ) + for match in pat.findall(query): + cleaned = match[0].strip() + if ( cleaned ): + yield cleaned +$$ language 'plpythonu' IMMUTABLE STRICT; diff --git a/scripts-available/CDB_Quota.sql b/scripts-available/CDB_Quota.sql index f8bfab2..4b5ca0b 100644 --- a/scripts-available/CDB_Quota.sql +++ b/scripts-available/CDB_Quota.sql @@ -50,7 +50,7 @@ BEGIN RETURN NEW; END IF; - SELECT CDB_UserDataSize() INTO quota; + SELECT public.CDB_UserDataSize() INTO quota; IF quota > qmax THEN RAISE EXCEPTION 'Quota exceeded by %KB', (quota-qmax)/1024; ELSE RAISE DEBUG 'User quota in bytes: % < % (max allowed)', quota, qmax; diff --git a/scripts-available/CDB_Roles.sql b/scripts-available/CDB_Roles.sql deleted file mode 100644 index c984d3c..0000000 --- a/scripts-available/CDB_Roles.sql +++ /dev/null @@ -1,13 +0,0 @@ -DO LANGUAGE 'plpgsql' $$ -BEGIN - IF NOT EXISTS ( SELECT * FROM pg_roles WHERE rolname= 'cdb_org_admin' ) - THEN - CREATE ROLE cdb_org_admin NOLOGIN; - END IF; - - IF NOT EXISTS ( SELECT * FROM pg_roles WHERE rolname= 'cdb_org_user' ) - THEN - CREATE ROLE cdb_org_user NOLOGIN; - END IF; -END -$$; diff --git a/scripts-available/CDB_StringToDate.sql b/scripts-available/CDB_StringToDate.sql index cbdf4ec..fa2db05 100644 --- a/scripts-available/CDB_StringToDate.sql +++ b/scripts-available/CDB_StringToDate.sql @@ -2,7 +2,7 @@ -- CREATE OR REPLACE FUNCTION CDB_StringToDate(input character varying) RETURNS date AS $$ -DECLARE output DATE DEFAULT NULL; +DECLARE output DATE; BEGIN BEGIN output := input::date; diff --git a/scripts-available/CDB_TableIndexes.sql b/scripts-available/CDB_TableIndexes.sql index c6871fe..c0ae98d 100644 --- a/scripts-available/CDB_TableIndexes.sql +++ b/scripts-available/CDB_TableIndexes.sql @@ -17,10 +17,11 @@ AS $$ ON pg_class.oid = idx.indexrelid WHERE pg_indexes.tablename = '' || $1 || '' AND '' || $1 || '' IN (SELECT CDB_UserTables()) - AND pg_class.relname=pg_indexes.indexname; + AND pg_class.relname=pg_indexes.indexname + ; $$ LANGUAGE SQL; --- This is a private function, so only the db owner need privileges -REVOKE ALL ON FUNCTION CDB_TableIndexes(REGCLASS) FROM PUBLIC; -GRANT EXECUTE ON FUNCTION CDB_TableIndexes(REGCLASS) TO ":DATABASE_USERNAME"; +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION CDB_TableIndexes(REGCLASS) TO public; diff --git a/scripts-available/CDB_UserTables.sql b/scripts-available/CDB_UserTables.sql index e8654ca..40e2f51 100644 --- a/scripts-available/CDB_UserTables.sql +++ b/scripts-available/CDB_UserTables.sql @@ -5,7 +5,6 @@ -- -- Currently accepted permissions are: 'public', 'private' or 'all' -- -DROP FUNCTION IF EXISTS CDB_UserTables(); -- replaced by: CREATE OR REPLACE FUNCTION CDB_UserTables(perm text DEFAULT 'all') RETURNS SETOF information_schema.sql_identifier AS $$ @@ -26,14 +25,17 @@ AS $$ FROM usertables ) SELECT t FROM perms - WHERE p = CASE WHEN $1 = 'private' THEN false + WHERE ( + p = CASE WHEN $1 = 'private' THEN false WHEN $1 = 'public' THEN true ELSE not p -- none END OR $1 = 'all' + ) + AND has_table_privilege('public'||'.'||t, 'SELECT') ; $$ LANGUAGE 'sql'; --- This is a private function, so only the db owner need privileges -REVOKE ALL ON FUNCTION CDB_UserTables(text) FROM PUBLIC; -GRANT EXECUTE ON FUNCTION CDB_UserTables(text) TO ":DATABASE_USERNAME"; +-- This is to migrate from pre-0.2.0 version +-- See http://github.com/CartoDB/cartodb-postgresql/issues/36 +GRANT EXECUTE ON FUNCTION CDB_UserTables(text) TO public; diff --git a/sql/test_ddl_triggers.sql b/sql/test_ddl_triggers.sql index 77fc23b..eae97c5 100644 --- a/sql/test_ddl_triggers.sql +++ b/sql/test_ddl_triggers.sql @@ -3,6 +3,9 @@ -- Set user quota to infinite SELECT CDB_SetUserQuotaInBytes(0); +-- Enable ddl triggers +SELECT cartodb.cdb_enable_ddl_hooks(); + create schema c; CREATE USER cartodb_postgresql_unpriv_user; @@ -26,7 +29,20 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)) as age -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; + +-- 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; +select + tabname::text, + round(extract('secs' from now() - updated_at)) as age +FROM CDB_TableMetadata WHERE tabname = 'c.t4'::regclass; ---------------------------- -- ALTER TABLE RENAME COLUMN @@ -45,7 +61,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; select pg_sleep(.1); alter table c.t3 rename column the_geom_webmercator to webmerc2; @@ -60,7 +76,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; ---------------------------- -- ALTER TABLE DROP COLUMN @@ -79,7 +95,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; ---------------------------- -- ALTER TABLE ADD COLUMN @@ -98,7 +114,7 @@ from c.t3; select tabname::text, round(extract('secs' from now() - updated_at)*10) as agecs -FROM CDB_TableMetadata; +FROM CDB_TableMetadata WHERE tabname = 'c.t3'::regclass; ---------------------------- -- DROP TABLE @@ -106,7 +122,7 @@ FROM CDB_TableMetadata; RESET SESSION AUTHORIZATION; drop schema c cascade; -select count(*) from CDB_TableMetadata; +select count(*) from CDB_TableMetadata; DROP USER cartodb_postgresql_unpriv_user; DROP FUNCTION _CDB_UserQuotaInBytes(); diff --git a/sql/test_setup.sql b/sql/test_setup.sql index 1f4bf2a..c05769f 100644 --- a/sql/test_setup.sql +++ b/sql/test_setup.sql @@ -1,5 +1,6 @@ CREATE EXTENSION postgis; CREATE EXTENSION schema_triggers; +CREATE EXTENSION plpythonu; CREATE EXTENSION cartodb; CREATE FUNCTION public.cdb_invalidate_varnish(table_name text) RETURNS void AS $$ diff --git a/test/CDB_CartodbfyTableTest.sql b/test/CDB_CartodbfyTableTest.sql index a57be77..74ece18 100644 --- a/test/CDB_CartodbfyTableTest.sql +++ b/test/CDB_CartodbfyTableTest.sql @@ -146,28 +146,82 @@ DROP TABLE t; CREATE TABLE t AS SELECT ST_SetSRID(ST_MakePoint(-1,-1),4326) as the_geom UNION ALL SELECT ST_SetSRID(ST_MakePoint(0,0),3857); SELECT CDB_CartodbfyTableCheck('t', 'mixed-srid the_geom'); -SELECT 'extent',ST_Extent(the_geom) FROM t; +SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)) FROM t; DROP TABLE t; -- table with wrong srid-constrained the_geom values CREATE TABLE t AS SELECT 'SRID=3857;LINESTRING(222638.981586547 222684.208505545, 111319.490793274 111325.142866385)'::geometry(geometry,3857) as the_geom; SELECT CDB_CartodbfyTableCheck('t', 'wrong srid-constrained the_geom'); -SELECT 'extent',ST_Extent(the_geom),ST_Extent(ST_SnapToGrid(the_geom_webmercator,1)) FROM t; +SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)),ST_Extent(ST_SnapToGrid(the_geom_webmercator,1)) FROM t; DROP TABLE t; -- table with wrong srid-constrained the_geom_webmercator values (and no the_geom!) CREATE TABLE t AS SELECT 'SRID=4326;LINESTRING(1 1,2 2)'::geometry(geometry,4326) as the_geom_webmercator; SELECT CDB_CartodbfyTableCheck('t', 'wrong srid-constrained the_geom_webmercator'); -- expect the_geom to be populated from the_geom_webmercator -SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.1)) FROM t; +SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.2)) FROM t; DROP TABLE t; -- table with existing triggered the_geom CREATE TABLE t AS SELECT 'SRID=4326;LINESTRING(1 1,2 2)'::geometry(geometry) as the_geom; CREATE TRIGGER update_the_geom_webmercator_trigger BEFORE UPDATE OF the_geom ON t - FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator(); + FOR EACH ROW EXECUTE PROCEDURE _CDB_update_the_geom_webmercator(); SELECT CDB_CartodbfyTableCheck('t', 'trigger-protected the_geom'); -SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.1)) FROM t; +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; + +-- 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; + +-- table with existing cartodb_id field of type int4 not sequenced +CREATE TABLE t AS SELECT 1::int4 as cartodb_id; +SELECT CDB_CartodbfyTableCheck('t', 'unsequenced cartodb_id'); +select cartodb_id FROM t; +DROP TABLE t; + +-- table with existing cartodb_id serial primary key +CREATE TABLE t ( cartodb_id serial primary key ); +SELECT CDB_CartodbfyTableCheck('t', 'cartodb_id serial primary key'); +SELECT c.conname, a.attname FROM pg_constraint c, pg_attribute a +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 diff --git a/test/CDB_CartodbfyTableTest_expect b/test/CDB_CartodbfyTableTest_expect index b66c318..c5e79e6 100644 --- a/test/CDB_CartodbfyTableTest_expect +++ b/test/CDB_CartodbfyTableTest_expect @@ -25,5 +25,31 @@ CREATE TRIGGER 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 +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_QueryStatementsTest.sql b/test/CDB_QueryStatementsTest.sql index c1c5424..7e8873c 100644 --- a/test/CDB_QueryStatementsTest.sql +++ b/test/CDB_QueryStatementsTest.sql @@ -26,3 +26,38 @@ INSER INTO "my''""t" values ('''','""'';;'); SELECT $qu;oted$ hi $qu;oted$; $the_param$) as statement ) SELECT '5', row_number() over (), statement FROM q; + +WITH q AS ( SELECT CDB_QueryStatements($the_param$ +SELECT +1 ; SELECT +2 +$the_param$) as statement ) +SELECT '6', row_number() over (), statement FROM q; + +-- This is an insane input, illegal sql +-- we are really only testing that it does not +-- take forever to process.. +-- The actual result is not correct, so if the function +-- ever gets fixed check if it's better +WITH q AS ( SELECT CDB_QueryStatements($the_param$ + + + + + + + + + /a + $b$ + $c$d + ; +$the_param$) as statement ) +SELECT '7', row_number() over (), statement FROM q; + + +WITH q AS ( SELECT CDB_QueryStatements($the_param$ +SELECT $quoted$ hi +$quoted$; +$the_param$) as statement ) +SELECT '8', row_number() over (), statement FROM q; diff --git a/test/CDB_QueryStatementsTest_expect b/test/CDB_QueryStatementsTest_expect index 9ed8fb1..7334d4b 100644 --- a/test/CDB_QueryStatementsTest_expect +++ b/test/CDB_QueryStatementsTest_expect @@ -7,3 +7,13 @@ 4|4|SELECT 5 5|1|INSER INTO "my''""t" values ('''','""'';;') 5|2|SELECT $qu;oted$ hi $qu;oted$ +6|1|SELECT +1 +6|2|SELECT +2 +7|1|/a +7|2|b +7|3|c +7|4|d +8|1|SELECT $quoted$ hi +$quoted$ diff --git a/test/CDB_UserTables.sql b/test/CDB_UserTablesTest.sql similarity index 100% rename from test/CDB_UserTables.sql rename to test/CDB_UserTablesTest.sql diff --git a/test/CDB_UserTables_expect b/test/CDB_UserTablesTest_expect similarity index 100% rename from test/CDB_UserTables_expect rename to test/CDB_UserTablesTest_expect diff --git a/test/README b/test/README new file mode 100644 index 0000000..6dcf328 --- /dev/null +++ b/test/README @@ -0,0 +1,15 @@ +Adding tests consists in adding 2 files in this directory: one file +containing the sql code and another containing the expected output. + +Example, to add a test for CDB_Something function, you'd add: + + - CDB_SomethingTest.sql + - CDB_SomethingTest_expect + +To easy the generation of the expected file you can initially omit it, +then run "make -C .. installcheck" from the top-level dir and copy +../results/test/CDB_SomethingTest.out to CDB_SomethingTest_expect chopping +off the first line: + + make -C .. installcheck + tail -n +2 ../results/test/CDB_SomethingTest.out > CDB_SomethingTest_expect diff --git a/util/create_from_unpackaged.sh b/util/create_from_unpackaged.sh index 7b3cf69..109c9ae 100755 --- a/util/create_from_unpackaged.sh +++ b/util/create_from_unpackaged.sh @@ -4,7 +4,22 @@ ver=$1 input=cartodb--${ver}.sql output=cartodb--unpackaged--${ver}.sql -cat ${input} | grep -v 'duplicated extension$' > ${output} +echo "-- Script generated by $0 on `date`" > ${output} + +# Migrate CDB functions from public schema to cartodb schema +cat ${input} | + grep '^ *CREATE OR REPLACE FUNCTION' | + grep -v ' cartodb\.' | # should only match DDL hooks + sed 's/).*$/)/' | + sed 's/DEFAULT [^ ,)]*//g' | + sed 's/CREATE OR REPLACE FUNCTION /ALTER FUNCTION public./' | + sed 's/$/ SET SCHEMA cartodb;/' | + sed 's/^/DO LANGUAGE plpgsql \$\$ BEGIN /' | + sed "s/$/ EXCEPTION WHEN OTHERS THEN RAISE NOTICE 'Got % (%)', SQLERRM, SQLSTATE; END; \$\$;/" | + cat >> ${output} + +# Upgrade all functions +cat ${input} | grep -v 'duplicated extension$' >> ${output} # Migrate CDB_TableMetadata cat >> ${output} <<'EOF' @@ -29,32 +44,34 @@ BEGIN DROP FUNCTION public._CDB_UserQuotaInBytes(); END; $$ LANGUAGE 'plpgsql'; - --- Cartodbfy tables with a trigger using 'CDB_CheckQuota' or --- 'CDB_TableMetadata_Trigger' from the 'public' schema -select cartodb.CDB_CartodbfyTable(relname::regclass) from ( - -- names of tables using public.CDB_CheckQuota or - -- public.CDB_TableMetadata_Trigger in their triggers - SELECT distinct c.relname - FROM - pg_trigger t, - pg_class c, - pg_proc p, - pg_namespace n - WHERE - n.nspname = 'public' AND - p.pronamespace = n.oid AND - p.proname IN ( 'cdb_checkquota', 'cdb_tablemetadata_trigger' ) AND - t.tgrelid = c.oid AND - p.oid = t.tgfoid -) as foo; EOF -# Drop functions from public schema -cat ${input} | - grep '^ *CREATE OR REPLACE FUNCTION' | - grep -v ' cartodb\.' | # should only match DDL hooks - sed 's/).*$/);/' | - sed 's/DEFAULT [^ ,)]*//g' | - sed 's/CREATE OR REPLACE FUNCTION /DROP FUNCTION public./' | - cat >> ${output} +## Cartodbfy tables with a trigger using 'CDB_CheckQuota' or +## 'CDB_TableMetadata_Trigger' from the 'public' schema +#cat >> ${output} <<'EOF' +#select cartodb.CDB_CartodbfyTable(relname::regclass) from ( +# -- names of tables using public.CDB_CheckQuota or +# -- public.CDB_TableMetadata_Trigger in their triggers +# SELECT distinct c.relname +# FROM +# pg_trigger t, +# pg_class c, +# pg_proc p, +# pg_namespace n +# WHERE +# n.nspname = 'public' AND +# p.pronamespace = n.oid AND +# p.proname IN ( 'cdb_checkquota', 'cdb_tablemetadata_trigger' ) AND +# t.tgrelid = c.oid AND +# p.oid = t.tgfoid +#) as foo; +#EOF + +## Drop any leftover function from public schema (there should be none) +#cat ${input} | +# grep '^ *CREATE OR REPLACE FUNCTION' | +# grep -v ' cartodb\.' | # should only match DDL hooks +# sed 's/).*$/);/' | +# sed 's/DEFAULT [^ ,)]*//g' | +# sed 's/CREATE OR REPLACE FUNCTION /DROP FUNCTION IF EXISTS public./' | +# cat >> ${output} diff --git a/util/create_upgrade.sh b/util/create_upgrade.sh new file mode 100755 index 0000000..8b49ceb --- /dev/null +++ b/util/create_upgrade.sh @@ -0,0 +1,9 @@ +#!/bin/sh + +fromver=$1 +ver=$2 +input=cartodb--${ver}.sql +output=cartodb--${fromver}--${ver}.sql + +cat ${input} | grep -v 'duplicated extension$' > ${output} +