Compare commits
34 Commits
| Author | SHA1 | Date | |
|---|---|---|---|
|
|
c9ff282b17 | ||
|
|
f251e12d35 | ||
|
|
5a3b93fd6b | ||
|
|
eaee6d3d70 | ||
|
|
7840e7c50b | ||
|
|
5b0a7bf9ad | ||
|
|
2ef6d5901e | ||
|
|
3d37b3646e | ||
|
|
51d48c7629 | ||
|
|
25a0e5ec68 | ||
|
|
daa61a6aa8 | ||
|
|
723a08e814 | ||
|
|
41a2c7363e | ||
|
|
45d07bc5a8 | ||
|
|
55615e1a32 | ||
|
|
4b397d6bc0 | ||
|
|
8349e3c94c | ||
|
|
a747f16ecc | ||
|
|
93de996acc | ||
|
|
a98b100182 | ||
|
|
72d8cf6210 | ||
|
|
6c57640901 | ||
|
|
a67f324001 | ||
|
|
5bb638b995 | ||
|
|
2637742c2e | ||
|
|
b75b492490 | ||
|
|
f9ec3c46ee | ||
|
|
679af1d4a3 | ||
|
|
6d665ab163 | ||
|
|
e5c8015e17 | ||
|
|
f61d07518d | ||
|
|
b5589fdf09 | ||
|
|
de2d3f818e | ||
|
|
9500010a67 |
1
.gitignore
vendored
1
.gitignore
vendored
@@ -5,3 +5,4 @@ results/
|
||||
regression.*
|
||||
expected/test
|
||||
sql/test
|
||||
.idea/*
|
||||
@@ -4,6 +4,7 @@ addons:
|
||||
postgresql: 9.3
|
||||
|
||||
before_install:
|
||||
- sudo apt-get update
|
||||
#- sudo apt-get install -q postgresql-9.3-postgis-2.1
|
||||
- sudo apt-get update
|
||||
- sudo apt-get install -q postgresql-server-dev-9.3
|
||||
|
||||
@@ -19,7 +19,7 @@ in which those scripts are loaded.
|
||||
|
||||
Scripts would be best coded in a way to be usable both for creation
|
||||
and upgrade of the objects. This means using CREATE OR REPLACE for
|
||||
the functions, and whatever it takes to check existance of any previous
|
||||
the functions, and whatever it takes to check existence of any previous
|
||||
version of objects in other cases.
|
||||
|
||||
When used as an extension (probably always from version 0.2.0 onwards)
|
||||
@@ -27,8 +27,8 @@ all the objects will be installed in a "cartodb" schema. Take this into
|
||||
account to fully-qualify internal calls to avoid (possibly dangerous)
|
||||
name clashes.
|
||||
|
||||
Every new feature (as well as bugfixes) should come with a testcase,
|
||||
see next session.
|
||||
Every new feature (as well as bugfixes) should come with a test case,
|
||||
see next section.
|
||||
|
||||
Writing testcases
|
||||
-----------------
|
||||
@@ -58,4 +58,3 @@ Starting with 0.2.0, the in-place reload can be done with an ad-hoc function:
|
||||
```sql
|
||||
SELECT cartodb.cdb_extension_reload();
|
||||
```
|
||||
|
||||
11
Makefile
11
Makefile
@@ -1,7 +1,7 @@
|
||||
# cartodb/Makefile
|
||||
|
||||
EXTENSION = cartodb
|
||||
EXTVERSION = 0.3.2
|
||||
EXTVERSION = 0.4.1
|
||||
|
||||
SED = sed
|
||||
|
||||
@@ -22,6 +22,12 @@ UPGRADABLE = \
|
||||
0.3.0 \
|
||||
0.3.0dev \
|
||||
0.3.1 \
|
||||
0.3.2 \
|
||||
0.3.3 \
|
||||
0.3.4 \
|
||||
0.3.5 \
|
||||
0.3.6 \
|
||||
0.4.0 \
|
||||
$(EXTVERSION)dev \
|
||||
$(EXTVERSION)next \
|
||||
$(END)
|
||||
@@ -32,7 +38,6 @@ UPGRADES = \
|
||||
$(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 = \
|
||||
@@ -74,7 +79,7 @@ $(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)/' $< > $@
|
||||
$(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' $< > $@
|
||||
|
||||
legacy_regress: $(REGRESS_OLD) Makefile
|
||||
mkdir -p sql/test/
|
||||
|
||||
@@ -1,3 +1,24 @@
|
||||
0.4.0 (2014-08-27)
|
||||
------------------
|
||||
Added CDB_Math_Mode function
|
||||
Changes in versioning: no revision is attached so it no longer uses `git describe` for the version.
|
||||
|
||||
0.3.6 (2014-08-11)
|
||||
------------------
|
||||
Dummy release to solve some issues with cdb branch/tag
|
||||
|
||||
0.3.5 (2014-08-11)
|
||||
------------------
|
||||
Inverting priority of CDB_CheckQuota qmax so gies more priority to existing user quota function over parameter value.
|
||||
|
||||
0.3.4 (2014-08-01)
|
||||
------------------
|
||||
Fixes issue with schemas in CDB_QueryTables
|
||||
|
||||
0.3.3 (2014-07-30)
|
||||
------------------
|
||||
* Splitting of CartodbfyTable method in subfunctions to be able to call in fragments and evade timeouts on hot zones
|
||||
|
||||
0.3.2 (2014-07-28)
|
||||
------------------
|
||||
* Make 0.3.0dev version upgradeable
|
||||
@@ -20,12 +20,16 @@ Dependencies
|
||||
Install
|
||||
-------
|
||||
|
||||
make all install
|
||||
```sh
|
||||
make all install
|
||||
```
|
||||
|
||||
Test installation
|
||||
-----------------
|
||||
|
||||
make installcheck
|
||||
```sh
|
||||
make installcheck
|
||||
```
|
||||
|
||||
NOTE: if ``test_ddl_triggers`` fails it's likely due to an incomplete
|
||||
installation of schema_triggers: you need to add ``schema_triggers.so``
|
||||
|
||||
@@ -6,54 +6,35 @@
|
||||
-- (user.rebuild_quota_trigger, called by rake task
|
||||
-- cartodb:db:update_test_quota_trigger)
|
||||
|
||||
-- Update the_geom_webmercator
|
||||
CREATE OR REPLACE FUNCTION _CDB_update_the_geom_webmercator()
|
||||
RETURNS trigger AS $$
|
||||
BEGIN
|
||||
NEW.the_geom_webmercator := public.CDB_TransformToWebmercator(NEW.the_geom);
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql VOLATILE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION _CDB_update_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at := now();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql VOLATILE;
|
||||
|
||||
-- Ensure a table is a "cartodb" table
|
||||
-- See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table
|
||||
CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(schema_name TEXT, reloid REGCLASS)
|
||||
RETURNS void
|
||||
-- 1) Required checks before running cartodbfication
|
||||
-- Either will pass silenty or raise an exception
|
||||
CREATE OR REPLACE FUNCTION _CDB_check_prerequisites(schema_name TEXT, reloid REGCLASS)
|
||||
RETURNS void
|
||||
AS $$
|
||||
DECLARE
|
||||
sql TEXT;
|
||||
rec RECORD;
|
||||
rec2 RECORD;
|
||||
tabinfo RECORD;
|
||||
had_column BOOLEAN;
|
||||
i INTEGER;
|
||||
new_name TEXT;
|
||||
quota_in_bytes INT8;
|
||||
exists_geom_cols BOOLEAN[];
|
||||
BEGIN
|
||||
|
||||
IF cartodb.schema_exists(schema_name) = false THEN
|
||||
RAISE EXCEPTION 'Invalid schema name "%"', schema_name;
|
||||
END IF;
|
||||
|
||||
-- TODO: Check that user quota is set ?
|
||||
BEGIN
|
||||
-- Content will be discarded
|
||||
EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name::text) INTO sql;
|
||||
EXCEPTION WHEN undefined_function THEN
|
||||
EXCEPTION WHEN undefined_function THEN
|
||||
RAISE EXCEPTION 'Please set user quota before cartodbfying tables.';
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
-- Drop cartodb triggers (might prevent changing columns)
|
||||
|
||||
-- 2) Drop cartodb triggers (might prevent changing columns)
|
||||
CREATE OR REPLACE FUNCTION _CDB_drop_triggers(reloid REGCLASS)
|
||||
RETURNS void
|
||||
AS $$
|
||||
DECLARE
|
||||
sql TEXT;
|
||||
BEGIN
|
||||
-- "track_updates"
|
||||
sql := 'DROP TRIGGER IF EXISTS track_updates ON ' || reloid::text;
|
||||
EXECUTE sql;
|
||||
@@ -71,10 +52,23 @@ BEGIN
|
||||
EXECUTE sql;
|
||||
sql := 'DROP TRIGGER IF EXISTS test_quota_per_row ON ' || reloid::text;
|
||||
EXECUTE sql;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
-- Ensure required fields exist
|
||||
|
||||
-- We need a cartodb_id column
|
||||
-- 3) Cartodb_id creation & validation or renaming if invalid
|
||||
CREATE OR REPLACE FUNCTION _CDB_create_cartodb_id_column(reloid REGCLASS)
|
||||
RETURNS void
|
||||
AS $$
|
||||
DECLARE
|
||||
sql TEXT;
|
||||
rec RECORD;
|
||||
rec2 RECORD;
|
||||
had_column BOOLEAN;
|
||||
i INTEGER;
|
||||
new_name TEXT;
|
||||
cartodb_id_name TEXT;
|
||||
BEGIN
|
||||
<< cartodb_id_setup >>
|
||||
LOOP --{
|
||||
had_column := FALSE;
|
||||
@@ -82,18 +76,17 @@ BEGIN
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' ADD cartodb_id SERIAL NOT NULL UNIQUE';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
cartodb_id_name := 'cartodb_id';
|
||||
EXIT cartodb_id_setup;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
RAISE NOTICE 'Column cartodb_id already exists';
|
||||
had_column := TRUE;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)',
|
||||
reloid, SQLERRM, SQLSTATE;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
RAISE NOTICE 'Column cartodb_id already exists';
|
||||
had_column := TRUE;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE;
|
||||
END;
|
||||
|
||||
IF had_column THEN
|
||||
|
||||
SELECT pg_catalog.pg_get_serial_sequence(reloid::text, 'cartodb_id')
|
||||
AS seq INTO rec2;
|
||||
|
||||
@@ -101,9 +94,9 @@ BEGIN
|
||||
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'
|
||||
WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = 'cartodb_id'
|
||||
INTO STRICT rec;
|
||||
|
||||
-- 20=int2, 21=int4, 23=int8
|
||||
IF rec.oid NOT IN (20,21,23) THEN -- {
|
||||
RAISE NOTICE 'Existing cartodb_id field is of invalid type % (need int2, int4 or int8), renaming', rec.typname;
|
||||
@@ -112,28 +105,27 @@ BEGIN
|
||||
ELSE -- }{
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' ALTER COLUMN cartodb_id SET NOT NULL';
|
||||
IF NOT EXISTS ( SELECT c.conname FROM pg_constraint c, pg_attribute a
|
||||
WHERE c.conkey = ARRAY[a.attnum] AND c.conrelid = reloid
|
||||
AND a.attrelid = reloid
|
||||
AND NOT a.attisdropped
|
||||
AND a.attname = 'cartodb_id'
|
||||
AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey
|
||||
WHERE c.conkey = ARRAY[a.attnum] AND c.conrelid = reloid
|
||||
AND a.attrelid = reloid
|
||||
AND NOT a.attisdropped
|
||||
AND a.attname = 'cartodb_id'
|
||||
AND c.contype IN ( 'u', 'p' ) ) -- unique or pkey
|
||||
THEN
|
||||
sql := sql || ', ADD unique(cartodb_id)';
|
||||
END IF;
|
||||
BEGIN
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
cartodb_id_name := 'cartodb_id';
|
||||
EXIT cartodb_id_setup;
|
||||
EXCEPTION
|
||||
WHEN unique_violation OR not_null_violation THEN
|
||||
RAISE NOTICE '%, renaming', SQLERRM;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)',
|
||||
reloid, SQLERRM, SQLSTATE;
|
||||
EXCEPTION
|
||||
WHEN unique_violation OR not_null_violation THEN
|
||||
RAISE NOTICE '%, renaming', SQLERRM;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE;
|
||||
END;
|
||||
END IF; -- }
|
||||
|
||||
|
||||
-- invalid column, need rename and re-create it
|
||||
i := 0;
|
||||
<< rename_column >>
|
||||
@@ -143,18 +135,17 @@ BEGIN
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN cartodb_id TO ' || new_name;
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
i := i+1;
|
||||
CONTINUE rename_column;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)',
|
||||
reloid, SQLERRM, SQLSTATE;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
i := i+1;
|
||||
CONTINUE rename_column;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (renaming cartodb_id): % (%)', reloid, SQLERRM, SQLSTATE;
|
||||
END;
|
||||
cartodb_id_name := new_name;
|
||||
EXIT rename_column;
|
||||
END LOOP; --}
|
||||
CONTINUE cartodb_id_setup;
|
||||
|
||||
END IF;
|
||||
END LOOP; -- }
|
||||
|
||||
@@ -163,12 +154,11 @@ BEGIN
|
||||
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
|
||||
-- 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';
|
||||
|| ' ALTER cartodb_id TYPE int USING '
|
||||
|| new_name || '::int4';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
|
||||
@@ -183,23 +173,51 @@ BEGIN
|
||||
|
||||
-- Reset sequence name
|
||||
sql := 'ALTER SEQUENCE ' || rec2.seq::text
|
||||
|| ' RESTART WITH ' || rec.max + 1;
|
||||
|| ' RESTART WITH ' || rec.max + 1;
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
|
||||
-- Drop old column (all went find if we got here)
|
||||
-- Drop old column (all went fine if we got here)
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' DROP ' || new_name;
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
|
||||
EXCEPTION
|
||||
WHEN others THEN
|
||||
RAISE NOTICE 'Could not initialize cartodb_id with existing values: % (%)',
|
||||
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
|
||||
-- Set primary key of the table if not already present (e.g. tables created from SQL API)
|
||||
IF cartodb_id_name IS NULL THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (Didnt get cartodb_id field name)', reloid;
|
||||
END IF;
|
||||
BEGIN
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' ADD PRIMARY KEY (cartodb_id)';
|
||||
EXECUTE sql;
|
||||
EXCEPTION
|
||||
WHEN others THEN
|
||||
RAISE DEBUG 'Table % Already had PRIMARY KEY', reloid;
|
||||
END;
|
||||
|
||||
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;
|
||||
@@ -208,48 +226,43 @@ BEGIN
|
||||
had_column := FALSE;
|
||||
BEGIN
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' ADD ' || rec.cname
|
||||
|| ' TIMESTAMPTZ NOT NULL DEFAULT now()';
|
||||
|| ' 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;
|
||||
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
|
||||
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 -- }{
|
||||
-- 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()';
|
||||
|| ' 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;
|
||||
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; -- }
|
||||
|
||||
@@ -262,18 +275,17 @@ cname, rec2.typname;
|
||||
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 %): % (%)',
|
||||
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; -- }
|
||||
|
||||
@@ -282,12 +294,11 @@ cname, rec2.typname;
|
||||
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
|
||||
-- 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';
|
||||
|| ' TYPE TIMESTAMPTZ USING '
|
||||
|| new_name || '::timestamptz';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
|
||||
@@ -296,21 +307,36 @@ cname, rec2.typname;
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
|
||||
EXCEPTION
|
||||
WHEN others THEN
|
||||
RAISE NOTICE 'Could not initialize % with existing values: % (%)',
|
||||
rec.cname, SQLERRM, SQLSTATE;
|
||||
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 || ')';
|
||||
|| ' GEOMETRY(geometry,' || rec.csrid || ')';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')';
|
||||
@@ -318,25 +344,22 @@ cname, rec2.typname;
|
||||
EXECUTE sql;
|
||||
exists_geom_cols := array_append(exists_geom_cols, false);
|
||||
EXIT column_setup;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
exists_geom_cols := array_append(exists_geom_cols, true);
|
||||
RAISE NOTICE 'Column % already exists', rec.cname;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (%): % (%)',
|
||||
reloid, rec.cname, SQLERRM, SQLSTATE;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
exists_geom_cols := array_append(exists_geom_cols, true);
|
||||
RAISE NOTICE 'Column % already exists', rec.cname;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (%): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
|
||||
END;
|
||||
|
||||
<< column_fixup >>
|
||||
LOOP --{
|
||||
|
||||
-- Check data type is a GEOMETRY
|
||||
SELECT t.typname, t.oid, a.attnotnull,
|
||||
postgis_typmod_srid(a.atttypmod) as srid,
|
||||
postgis_typmod_type(a.atttypmod) as gtype
|
||||
FROM pg_type t, pg_attribute a
|
||||
WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped
|
||||
AND a.attname = rec.cname
|
||||
postgis_typmod_srid(a.atttypmod) as srid,
|
||||
postgis_typmod_type(a.atttypmod) as gtype
|
||||
FROM pg_type t, pg_attribute a
|
||||
WHERE a.atttypid = t.oid AND a.attrelid = reloid AND NOT a.attisdropped AND a.attname = rec.cname
|
||||
INTO STRICT rec2;
|
||||
|
||||
IF rec2.typname NOT IN ('geometry') THEN -- {
|
||||
@@ -345,46 +368,44 @@ cname, rec2.typname;
|
||||
END IF; -- }
|
||||
|
||||
IF rec2.srid != rec.csrid THEN -- {
|
||||
BEGIN
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname
|
||||
|| ' TYPE geometry(' || rec2.gtype || ',' || rec.csrid || ') USING ST_Transform('
|
||||
|| rec.cname || ',' || rec.csrid || ')';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
BEGIN
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' ALTER ' || rec.cname
|
||||
|| ' TYPE geometry(' || rec2.gtype || ',' || rec.csrid || ') USING ST_Transform('
|
||||
|| rec.cname || ',' || rec.csrid || ')';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
EXCEPTION
|
||||
WHEN others THEN
|
||||
RAISE NOTICE 'Could not enforce SRID % to column %: %, renaming', rec.csrid, rec.cname, SQLERRM;
|
||||
EXIT column_fixup; -- cannot fix, will rename
|
||||
END;
|
||||
END;
|
||||
END IF; -- }
|
||||
|
||||
-- add gist indices if not there already
|
||||
IF NOT EXISTS ( SELECT ir.relname
|
||||
FROM pg_am am, pg_class ir,
|
||||
pg_class c, pg_index i,
|
||||
pg_attribute a
|
||||
pg_class c, pg_index i,
|
||||
pg_attribute a
|
||||
WHERE c.oid = reloid AND i.indrelid = c.oid
|
||||
AND a.attname = rec.cname
|
||||
AND i.indexrelid = ir.oid AND i.indnatts = 1
|
||||
AND i.indkey[0] = a.attnum AND a.attrelid = c.oid
|
||||
AND NOT a.attisdropped AND am.oid = ir.relam
|
||||
AND am.amname = 'gist' )
|
||||
AND a.attname = rec.cname
|
||||
AND i.indexrelid = ir.oid AND i.indnatts = 1
|
||||
AND i.indkey[0] = a.attnum AND a.attrelid = c.oid
|
||||
AND NOT a.attisdropped AND am.oid = ir.relam
|
||||
AND am.amname = 'gist' )
|
||||
THEN -- {
|
||||
BEGIN
|
||||
sql := 'CREATE INDEX ON ' || reloid::text || ' USING GIST ( ' || rec.cname || ')';
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
EXCEPTION
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (% index): % (%)',
|
||||
reloid, rec.cname, SQLERRM, SQLSTATE;
|
||||
EXCEPTION
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (% index): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
|
||||
END;
|
||||
END IF; -- }
|
||||
|
||||
-- if we reached this line, all went good
|
||||
EXIT column_setup;
|
||||
|
||||
END LOOP; -- } column_fixup
|
||||
END LOOP; -- } column_fixup
|
||||
|
||||
-- invalid column, need rename and re-create it
|
||||
i := 0;
|
||||
@@ -395,87 +416,155 @@ cname, rec2.typname;
|
||||
sql := 'ALTER TABLE ' || reloid::text || ' RENAME COLUMN ' || rec.cname || ' TO ' || new_name;
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
i := i+1;
|
||||
CONTINUE rename_column;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (rename %): % (%)',
|
||||
reloid, rec.cname, SQLERRM, SQLSTATE;
|
||||
EXCEPTION
|
||||
WHEN duplicate_column THEN
|
||||
i := i+1;
|
||||
CONTINUE rename_column;
|
||||
WHEN others THEN
|
||||
RAISE EXCEPTION 'Cartodbfying % (rename %): % (%)', reloid, rec.cname, SQLERRM, SQLSTATE;
|
||||
END;
|
||||
EXIT rename_column;
|
||||
END LOOP; --}
|
||||
CONTINUE column_setup;
|
||||
|
||||
END LOOP; -- } column_setup
|
||||
|
||||
END LOOP; -- } column_setup
|
||||
END LOOP; -- } on expected geometry columns
|
||||
|
||||
-- Initialize the_geom with values from the_geom_webmercator
|
||||
-- do this only if the_geom_webmercator was found (not created)
|
||||
-- _and_ the_geom was NOT found.
|
||||
IF exists_geom_cols[2] AND NOT exists_geom_cols[1] THEN
|
||||
sql := 'UPDATE ' || reloid::text || ' SET the_geom = ST_Transform(the_geom_webmercator, 4326) ';
|
||||
EXECUTE sql;
|
||||
END IF;
|
||||
|
||||
-- Initialize the_geom_webmercator with values from the_geom
|
||||
-- do this only if the_geom was found (not created)
|
||||
-- _and_ the_geom_webmercator was NOT found.
|
||||
IF exists_geom_cols[1] AND NOT exists_geom_cols[2] THEN
|
||||
sql := 'UPDATE ' || reloid::text || ' SET the_geom_webmercator = public.CDB_TransformToWebmercator(the_geom) ';
|
||||
EXECUTE sql;
|
||||
END IF;
|
||||
|
||||
-- Re-create all triggers
|
||||
|
||||
-- NOTE: drop/create has the side-effect of re-enabling disabled triggers
|
||||
|
||||
-- "track_updates"
|
||||
sql := 'CREATE trigger track_updates AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH STATEMENT EXECUTE PROCEDURE public.cdb_tablemetadata_trigger()';
|
||||
EXECUTE sql;
|
||||
|
||||
-- "update_the_geom_webmercator"
|
||||
-- TODO: why _before_ and not after ?
|
||||
sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()';
|
||||
EXECUTE sql;
|
||||
|
||||
-- "update_updated_at"
|
||||
-- TODO: why _before_ and not after ?
|
||||
sql := 'CREATE trigger update_updated_at_trigger BEFORE UPDATE ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_updated_at()';
|
||||
EXECUTE sql;
|
||||
|
||||
-- "test_quota" and "test_quota_per_row"
|
||||
|
||||
sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON '
|
||||
|| reloid::text
|
||||
|| ' EXECUTE PROCEDURE public.CDB_CheckQuota(1, ''-1'', '''
|
||||
|| schema_name::text
|
||||
|| ''')';
|
||||
EXECUTE sql;
|
||||
|
||||
sql := 'CREATE TRIGGER test_quota_per_row BEFORE UPDATE OR INSERT ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH ROW EXECUTE PROCEDURE public.CDB_CheckQuota(0.001, ''-1'', '''
|
||||
|| schema_name::text
|
||||
|| ''')';
|
||||
EXECUTE sql;
|
||||
|
||||
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) Create all triggers
|
||||
-- NOTE: drop/create has the side-effect of re-enabling disabled triggers
|
||||
CREATE OR REPLACE FUNCTION _CDB_create_triggers(schema_name TEXT, reloid REGCLASS)
|
||||
RETURNS void
|
||||
AS $$
|
||||
DECLARE
|
||||
sql TEXT;
|
||||
BEGIN
|
||||
-- "track_updates"
|
||||
sql := 'CREATE trigger track_updates AFTER INSERT OR UPDATE OR DELETE OR TRUNCATE ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH STATEMENT EXECUTE PROCEDURE public.cdb_tablemetadata_trigger()';
|
||||
EXECUTE sql;
|
||||
|
||||
-- "update_the_geom_webmercator"
|
||||
-- TODO: why _before_ and not after ?
|
||||
sql := 'CREATE trigger update_the_geom_webmercator_trigger BEFORE INSERT OR UPDATE OF the_geom ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_the_geom_webmercator()';
|
||||
EXECUTE sql;
|
||||
|
||||
-- "update_updated_at"
|
||||
-- TODO: why _before_ and not after ?
|
||||
sql := 'CREATE trigger update_updated_at_trigger BEFORE UPDATE ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH ROW EXECUTE PROCEDURE public._CDB_update_updated_at()';
|
||||
EXECUTE sql;
|
||||
|
||||
-- "test_quota" and "test_quota_per_row"
|
||||
|
||||
sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON '
|
||||
|| reloid::text
|
||||
|| ' EXECUTE PROCEDURE public.CDB_CheckQuota(1, ''-1'', '''
|
||||
|| schema_name::text
|
||||
|| ''')';
|
||||
EXECUTE sql;
|
||||
|
||||
sql := 'CREATE TRIGGER test_quota_per_row BEFORE UPDATE OR INSERT ON '
|
||||
|| reloid::text
|
||||
|| ' FOR EACH ROW EXECUTE PROCEDURE public.CDB_CheckQuota(0.001, ''-1'', '''
|
||||
|| schema_name::text
|
||||
|| ''')';
|
||||
EXECUTE sql;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
|
||||
-- Update the_geom_webmercator
|
||||
CREATE OR REPLACE FUNCTION _CDB_update_the_geom_webmercator()
|
||||
RETURNS trigger
|
||||
AS $$
|
||||
BEGIN
|
||||
NEW.the_geom_webmercator := public.CDB_TransformToWebmercator(NEW.the_geom);
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql VOLATILE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION _CDB_update_updated_at()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.updated_at := now();
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql VOLATILE;
|
||||
|
||||
|
||||
-- ////////////////////////////////////////////////////
|
||||
|
||||
-- Ensure a table is a "cartodb" table
|
||||
-- See https://github.com/CartoDB/cartodb/wiki/CartoDB-user-table
|
||||
CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(schema_name TEXT, reloid REGCLASS)
|
||||
RETURNS void
|
||||
AS $$
|
||||
DECLARE
|
||||
exists_geom_cols BOOLEAN[];
|
||||
BEGIN
|
||||
|
||||
PERFORM cartodb._CDB_check_prerequisites(schema_name, reloid);
|
||||
|
||||
PERFORM cartodb._CDB_drop_triggers(reloid);
|
||||
|
||||
-- Ensure required fields exist
|
||||
PERFORM cartodb._CDB_create_cartodb_id_column(reloid);
|
||||
PERFORM cartodb._CDB_create_timestamp_columns(reloid);
|
||||
SELECT cartodb._CDB_create_the_geom_columns(reloid) INTO exists_geom_cols;
|
||||
|
||||
-- Both only populate if proceeds
|
||||
PERFORM cartodb._CDB_populate_the_geom_from_the_geom_webmercator(reloid, exists_geom_cols);
|
||||
PERFORM cartodb._CDB_populate_the_geom_webmercator_from_the_geom(reloid, exists_geom_cols);
|
||||
|
||||
PERFORM cartodb._CDB_create_triggers(schema_name, reloid);
|
||||
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
CREATE OR REPLACE FUNCTION CDB_CartodbfyTable(reloid REGCLASS)
|
||||
RETURNS void
|
||||
AS $$
|
||||
BEGIN
|
||||
PERFORM public.CDB_CartodbfyTable('public', reloid);
|
||||
PERFORM cartodb.CDB_CartodbfyTable('public', reloid);
|
||||
END;
|
||||
$$
|
||||
LANGUAGE PLPGSQL;
|
||||
$$ LANGUAGE PLPGSQL;
|
||||
|
||||
26
scripts-available/CDB_Math.sql
Normal file
26
scripts-available/CDB_Math.sql
Normal file
@@ -0,0 +1,26 @@
|
||||
-- CartoDB Math SQL functions
|
||||
|
||||
|
||||
-- Mode
|
||||
-- https://wiki.postgresql.org/wiki/Aggregate_Mode
|
||||
|
||||
CREATE OR REPLACE FUNCTION cartodb._CDB_Math_final_mode(anyarray)
|
||||
RETURNS anyelement AS
|
||||
$BODY$
|
||||
SELECT a
|
||||
FROM unnest($1) a
|
||||
GROUP BY 1
|
||||
ORDER BY COUNT(1) DESC, 1
|
||||
LIMIT 1;
|
||||
$BODY$
|
||||
LANGUAGE 'sql' IMMUTABLE;
|
||||
|
||||
DROP AGGREGATE IF EXISTS cartodb.CDB_Math_Mode(anyelement);
|
||||
|
||||
CREATE AGGREGATE cartodb.CDB_Math_Mode(anyelement) (
|
||||
SFUNC=array_append,
|
||||
STYPE=anyarray,
|
||||
FINALFUNC=_CDB_Math_final_mode,
|
||||
INITCOND='{}'
|
||||
);
|
||||
|
||||
@@ -39,7 +39,7 @@ BEGIN
|
||||
inp AS (
|
||||
SELECT
|
||||
xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x,
|
||||
xpath('//x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s
|
||||
xpath('//x:Relation-Name/../x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s
|
||||
)
|
||||
SELECT unnest(x)::name as p, unnest(s)::name as sc from inp
|
||||
LOOP
|
||||
|
||||
@@ -46,16 +46,20 @@ BEGIN
|
||||
ELSE
|
||||
schema_name := 'public';
|
||||
END IF;
|
||||
-- Hack to support old versions of CDB_CheckQuota with 2 params but without schema_name
|
||||
IF TG_NARGS >= 2 AND TG_ARGV[1] <> '-1' THEN
|
||||
qmax := TG_ARGV[1];
|
||||
ELSE
|
||||
|
||||
-- By default try to use quota function, and if not present then rely on the one specified by params
|
||||
BEGIN
|
||||
EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name) INTO qmax;
|
||||
EXCEPTION WHEN undefined_function THEN
|
||||
BEGIN
|
||||
EXECUTE FORMAT('SELECT %I._CDB_UserQuotaInBytes();', schema_name) INTO qmax;
|
||||
EXCEPTION WHEN undefined_function THEN
|
||||
RAISE EXCEPTION 'Missing "%"._CDB_UserQuotaInBytes()', schema_name;
|
||||
IF TG_NARGS >= 2 AND TG_ARGV[1] <> '-1' THEN
|
||||
qmax := TG_ARGV[1];
|
||||
ELSE
|
||||
RAISE EXCEPTION 'Missing "%"._CDB_UserQuotaInBytes()', schema_name;
|
||||
END IF;
|
||||
END;
|
||||
END IF;
|
||||
END;
|
||||
|
||||
pbfact := TG_ARGV[0];
|
||||
|
||||
dice := random();
|
||||
|
||||
1
scripts-enabled/220-CDB_Math.sql
Symbolic link
1
scripts-enabled/220-CDB_Math.sql
Symbolic link
@@ -0,0 +1 @@
|
||||
../scripts-available/CDB_Math.sql
|
||||
@@ -2,6 +2,8 @@ SET
|
||||
CREATE FUNCTION
|
||||
SELECT 1
|
||||
ERROR: Please set user quota before cartodbfying tables.
|
||||
CONTEXT: SQL statement "SELECT cartodb._CDB_check_prerequisites(schema_name, reloid)"
|
||||
PL/pgSQL function cdb_cartodbfytable(text,regclass) line 6 at PERFORM
|
||||
0
|
||||
single non-geometrical column cartodbfied fine
|
||||
DROP TABLE
|
||||
|
||||
4
test/CDB_MathTest.sql
Normal file
4
test/CDB_MathTest.sql
Normal file
@@ -0,0 +1,4 @@
|
||||
|
||||
SELECT cdb_math_mode(a) from unnest(ARRAY[1,2,2,3]) a;
|
||||
SELECT cdb_math_mode(a) from unnest(ARRAY[1,2,3]) a;
|
||||
SELECT cdb_math_mode(a) from unnest(ARRAY[1]) a;
|
||||
3
test/CDB_MathTest_expect
Normal file
3
test/CDB_MathTest_expect
Normal file
@@ -0,0 +1,3 @@
|
||||
2
|
||||
1
|
||||
1
|
||||
@@ -7,7 +7,7 @@ ERROR: Quota exceeded by 3.9990234375KB
|
||||
|
||||
INSERT 0 1024
|
||||
8
|
||||
ERROR: Quota exceeded by 103.9921875KB
|
||||
ERROR: Quota exceeded by 123.9921875KB
|
||||
0
|
||||
INSERT 0 1
|
||||
DROP TABLE
|
||||
|
||||
@@ -325,6 +325,27 @@ function test_user_can_read_when_it_has_permission_after_organization_permission
|
||||
drop_role_and_schema cdb_testmember_3
|
||||
}
|
||||
|
||||
function test_cdb_querytables_returns_schema_and_table_name() {
|
||||
sql "CREATE EXTENSION plpythonu;"
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
|
||||
sql cdb_testmember_1 "select * from CDB_QueryTables('select * from foo');" should "{cdb_testmember_1.foo}"
|
||||
}
|
||||
|
||||
function test_cdb_querytables_returns_schema_and_table_name_for_several_schemas() {
|
||||
sql "CREATE EXTENSION plpythonu;"
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
|
||||
sql postgres "select * from CDB_QueryTables('select * from cdb_testmember_1.foo, cdb_testmember_2.bar');" should "{cdb_testmember_1.foo,cdb_testmember_2.bar}"
|
||||
}
|
||||
|
||||
function test_cdb_querytables_does_not_return_functions_as_part_of_the_resultset() {
|
||||
sql "CREATE EXTENSION plpythonu;"
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
|
||||
sql postgres "select * from CDB_QueryTables('select * from cdb_testmember_1.foo, cdb_testmember_2.bar, plainto_tsquery(''foo'')');" should "{cdb_testmember_1.foo,cdb_testmember_2.bar}"
|
||||
}
|
||||
|
||||
#################################################### TESTS END HERE ####################################################
|
||||
|
||||
|
||||
|
||||
Reference in New Issue
Block a user