Compare commits
34 Commits
| Author | SHA1 | Date | |
|---|---|---|---|
|
|
c6f2903221 | ||
|
|
03f42e36c9 | ||
|
|
af546b35ab | ||
|
|
5abe6e0b3d | ||
|
|
1eabc5e880 | ||
|
|
c6cdaea626 | ||
|
|
b5a9fb9fcf | ||
|
|
83b7f47617 | ||
|
|
25cf48d4a4 | ||
|
|
29efdf2ee7 | ||
|
|
4be7d4a497 | ||
|
|
350c76f847 | ||
|
|
d00e71309d | ||
|
|
07280321ab | ||
|
|
e28b6344aa | ||
|
|
2867a6fbad | ||
|
|
afecef0e31 | ||
|
|
7582f2cbc5 | ||
|
|
4b5c5dd275 | ||
|
|
eb6fc4fefb | ||
|
|
4fe85a6a76 | ||
|
|
2269dc0cb5 | ||
|
|
0ba57f436a | ||
|
|
a5ccbdddcf | ||
|
|
45383d7c8a | ||
|
|
0057e2ddec | ||
|
|
79cacb8ef4 | ||
|
|
14e2a65523 | ||
|
|
d723487f67 | ||
|
|
db323f3e13 | ||
|
|
49c4cea4e7 | ||
|
|
7f63688a2f | ||
|
|
7ed3c29f82 | ||
|
|
8c2252a9cb |
6
Makefile
6
Makefile
@@ -1,7 +1,7 @@
|
||||
# cartodb/Makefile
|
||||
|
||||
EXTENSION = cartodb
|
||||
EXTVERSION = 0.9.1
|
||||
EXTVERSION = 0.10.0
|
||||
|
||||
SED = sed
|
||||
|
||||
@@ -44,6 +44,10 @@ UPGRADABLE = \
|
||||
0.8.2 \
|
||||
0.9.0 \
|
||||
0.9.1 \
|
||||
0.9.2 \
|
||||
0.9.3 \
|
||||
0.9.4 \
|
||||
0.10.0 \
|
||||
$(EXTVERSION)dev \
|
||||
$(EXTVERSION)next \
|
||||
$(END)
|
||||
|
||||
19
NEWS.md
19
NEWS.md
@@ -1,3 +1,22 @@
|
||||
0.10.0 (2015-09-07)
|
||||
-----------------
|
||||
* Quote schema and table names returned by CDB_QueryTables [#134](https://github.com/CartoDB/cartodb-postgresql/pull/134). Use quote_ident to quote schema and table names when necessary.
|
||||
* Fixed CDB_ColumnNames [#122](https://github.com/CartoDB/cartodb-postgresql/issues/122) and CDB_ColumnType [#130](https://github.com/CartoDB/cartodb-postgresql/issues/130) should honor regclass, returning columns for just the table in the schema and not in any other one [#131](https://github.com/CartoDB/cartodb-postgresql/pull/131).
|
||||
* Add kurtosis and skewness [#124](https://github.com/CartoDB/cartodb-postgresql/pull/124).
|
||||
* Removed `DROP FUNCTION IF EXISTS cdb_usertables(text);` [#129](https://github.com/CartoDB/cartodb-postgresql/pull/129). This was needed for upgrading between 0.7.4 to 0.8.0 but is no longer needed.
|
||||
|
||||
0.9.4 (2015-08-28)
|
||||
------------------
|
||||
* Fixed issue with indices when renaming tables [#123](https://github.com/CartoDB/cartodb-postgresql/issues/123)
|
||||
|
||||
0.9.3 (2015-08-27)
|
||||
------------------
|
||||
* Modify sampling of quota trigger [#126](https://github.com/CartoDB/cartodb-postgresql/issues/126)
|
||||
|
||||
0.9.2 (2015-08-24)
|
||||
------------------
|
||||
* Fix for `the_geom` column present but not SRID (EWKT) and other corner cases [#121](https://github.com/CartoDB/cartodb-postgresql/pull/121)
|
||||
|
||||
0.9.1 (2015-08-19)
|
||||
------------------
|
||||
* Fix for transformation to webmercator in corner cases [#116](https://github.com/CartoDB/cartodb-postgresql/issues/116)
|
||||
|
||||
@@ -98,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 := Format('ALTER TABLE %s ALTER COLUMN cartodb_id SET NOT NULL', reloid::text);
|
||||
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
|
||||
@@ -127,7 +127,7 @@ BEGIN
|
||||
LOOP --{
|
||||
new_name := '_cartodb_id' || i;
|
||||
BEGIN
|
||||
sql := Format('ALTER TABLE %s RENAME COLUMN cartodb_id TO %I', reloid::text, new_name);
|
||||
sql := Format('ALTER TABLE %s RENAME COLUMN cartodb_id TO %I', reloid::text, new_name);
|
||||
RAISE DEBUG 'Running %', sql;
|
||||
EXECUTE sql;
|
||||
EXCEPTION
|
||||
@@ -222,7 +222,7 @@ BEGIN
|
||||
|
||||
sql := 'CREATE TRIGGER test_quota BEFORE UPDATE OR INSERT ON '
|
||||
|| reloid::text
|
||||
|| ' EXECUTE PROCEDURE public.CDB_CheckQuota(1, ''-1'', '''
|
||||
|| ' EXECUTE PROCEDURE public.CDB_CheckQuota(0.1, ''-1'', '''
|
||||
|| schema_name::text
|
||||
|| ''')';
|
||||
EXECUTE sql;
|
||||
@@ -654,17 +654,29 @@ END;
|
||||
$$ LANGUAGE 'plpgsql';
|
||||
|
||||
|
||||
DROP FUNCTION IF EXISTS _CDB_Has_Usable_Geom(regclass);
|
||||
CREATE OR REPLACE FUNCTION _CDB_Has_Usable_Geom(reloid REGCLASS)
|
||||
RETURNS BOOLEAN
|
||||
RETURNS RECORD
|
||||
AS $$
|
||||
DECLARE
|
||||
r1 RECORD;
|
||||
r2 RECORD;
|
||||
rv RECORD;
|
||||
|
||||
const RECORD;
|
||||
|
||||
has_geom BOOLEAN := false;
|
||||
has_mercgeom BOOLEAN := false;
|
||||
has_geom_name TEXT;
|
||||
has_mercgeom_name TEXT;
|
||||
|
||||
-- In case 'the_geom' is a text column
|
||||
text_geom_column BOOLEAN := false;
|
||||
text_geom_column_name TEXT := '';
|
||||
text_geom_column_srid BOOLEAN := true;
|
||||
|
||||
-- Utility variables
|
||||
srid INTEGER;
|
||||
str TEXT;
|
||||
sql TEXT;
|
||||
BEGIN
|
||||
@@ -694,13 +706,50 @@ BEGIN
|
||||
|
||||
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('checking column ''%s''', r1.attname);
|
||||
|
||||
-- Name collision: right name but wrong type, rename it!
|
||||
-- Name collision: right name (the_geom, the_geomwebmercator?) but wrong type...
|
||||
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);
|
||||
|
||||
-- Maybe it's a geometry column hiding in a text column?
|
||||
IF r1.typname IN ('text','varchar','char') THEN
|
||||
|
||||
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('column ''%s'' is a text column', r1.attname);
|
||||
|
||||
BEGIN
|
||||
sql := Format('SELECT Max(ST_SRID(%I::geometry)) AS srid FROM %I', r1.attname, reloid::text);
|
||||
EXECUTE sql INTO srid;
|
||||
-- This gets skipped if EXCEPTION happens
|
||||
-- Let the table writer know we need to convert from text
|
||||
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('column ''%s'' can be cast from text to geometry', r1.attname);
|
||||
text_geom_column := true;
|
||||
text_geom_column_name := r1.attname;
|
||||
-- Let the table writer know we need to force an SRID
|
||||
IF srid = 0 THEN
|
||||
text_geom_column_srid := false;
|
||||
END IF;
|
||||
-- Nope, the text in the column can't be converted into geometry
|
||||
-- so rename it out of the way
|
||||
EXCEPTION
|
||||
WHEN others THEN
|
||||
IF SQLERRM = 'parse error - invalid geometry' THEN
|
||||
text_geom_column := false;
|
||||
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('Text column %s is not convertible to geometry, renamed to %s', r1.attname, str);
|
||||
ELSE
|
||||
RAISE EXCEPTION 'CDB(_CDB_Has_Usable_Geom) UNEXPECTED ERROR';
|
||||
END IF;
|
||||
END;
|
||||
|
||||
-- Just change its name so we can write a new column into that name.
|
||||
ELSE
|
||||
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);
|
||||
END IF;
|
||||
|
||||
-- Found a geometry column!
|
||||
ELSIF r1.typname = 'geometry' THEN
|
||||
@@ -719,6 +768,12 @@ BEGIN
|
||||
has_mercgeom_name := r1.attname;
|
||||
END IF;
|
||||
|
||||
-- If it's an unknown SRID, we need to know that too
|
||||
ELSIF r1.srid = 0 OR _CDB_Geometry_SRID(reloid, r1.attname) = 0 THEN
|
||||
|
||||
-- Unknown SRID, we'll have to fill it in later
|
||||
text_geom_column_srid := true;
|
||||
|
||||
END IF;
|
||||
|
||||
END IF;
|
||||
@@ -737,13 +792,20 @@ BEGIN
|
||||
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;
|
||||
SELECT
|
||||
-- If table is perfect (no transforms required), return TRUE!
|
||||
has_geom AND has_mercgeom AS has_usable_geoms,
|
||||
-- If the geometry column is hiding in a text field, return enough info to deal w/ it.
|
||||
text_geom_column, text_geom_column_name, text_geom_column_srid
|
||||
INTO rv;
|
||||
|
||||
RAISE DEBUG 'CDB(_CDB_Has_Usable_Geom): %', Format('returning %s', rv);
|
||||
|
||||
RETURN rv;
|
||||
|
||||
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
|
||||
@@ -771,12 +833,13 @@ DECLARE
|
||||
|
||||
rec RECORD;
|
||||
const RECORD;
|
||||
gc RECORD;
|
||||
sql TEXT;
|
||||
str TEXT;
|
||||
table_srid INTEGER;
|
||||
geom_srid INTEGER;
|
||||
|
||||
has_usable_primary_key BOOLEAN;
|
||||
has_usable_geoms BOOLEAN;
|
||||
|
||||
BEGIN
|
||||
|
||||
@@ -799,7 +862,7 @@ BEGIN
|
||||
-- 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
|
||||
SELECT _CDB_Has_Usable_Primary_ID(reloid)
|
||||
INTO STRICT has_usable_primary_key;
|
||||
|
||||
RAISE DEBUG 'CDB(_CDB_Rewrite_Table): has_usable_primary_key %', has_usable_primary_key;
|
||||
@@ -808,24 +871,29 @@ BEGIN
|
||||
-- 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;
|
||||
SELECT *
|
||||
FROM _CDB_Has_Usable_Geom(reloid)
|
||||
AS (has_usable_geoms boolean,
|
||||
text_geom_column boolean,
|
||||
text_geom_column_name text,
|
||||
text_geom_column_srid boolean)
|
||||
INTO STRICT gc;
|
||||
|
||||
RAISE DEBUG 'CDB(_CDB_Rewrite_Table): has_usable_geoms %', has_usable_geoms;
|
||||
RAISE DEBUG 'CDB(_CDB_Rewrite_Table): has_usable_geoms %', gc.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
|
||||
IF has_usable_primary_key AND gc.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
|
||||
ELSIF has_usable_primary_key AND gc.has_usable_geoms AND destschema = relschema THEN
|
||||
|
||||
RAISE DEBUG 'CDB(_CDB_Rewrite_Table): perfect table in the perfect place';
|
||||
RETURN true;
|
||||
@@ -848,7 +916,6 @@ BEGIN
|
||||
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;
|
||||
|
||||
@@ -863,78 +930,133 @@ BEGIN
|
||||
END IF;
|
||||
|
||||
-- Add the geometry columns!
|
||||
IF has_usable_geoms THEN
|
||||
IF gc.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;
|
||||
|
||||
-- Arg, this "geometry" column is actually text!!
|
||||
-- OK, we tested back in our geometry column research that it could
|
||||
-- be safely cast to geometry, so let's do that.
|
||||
IF gc.text_geom_column THEN
|
||||
|
||||
WITH t AS (
|
||||
SELECT
|
||||
a.attname,
|
||||
CASE WHEN NOT gc.text_geom_column_srid THEN 'ST_SetSRID(' ELSE '' END AS missing_srid_start,
|
||||
CASE WHEN NOT gc.text_geom_column_srid THEN ',4326)' ELSE '' END AS missing_srid_end
|
||||
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 IN ('text','varchar','char')
|
||||
AND a.attnum > 0
|
||||
AND a.attname = gc.text_geom_column_name
|
||||
AND NOT a.attisdropped
|
||||
ORDER BY a.attnum
|
||||
LIMIT 1
|
||||
)
|
||||
SELECT ', ST_Transform('
|
||||
|| t.missing_srid_start || t.attname || '::geometry' || t.missing_srid_end
|
||||
|| ',4326)::Geometry(GEOMETRY,4326) AS '
|
||||
|| const.geomcol
|
||||
|| ', cartodb.CDB_TransformToWebmercator('
|
||||
|| t.missing_srid_start || t.attname || '::geometry' || t.missing_srid_end
|
||||
|| ')::Geometry(GEOMETRY,3857) AS '
|
||||
|| const.mercgeomcol,
|
||||
t.attname
|
||||
INTO geom_transform_sql, geom_column_source
|
||||
FROM t;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
-- We checked that this column existed already, it bloody well
|
||||
-- better be found.
|
||||
RAISE EXCEPTION 'CDB(_CDB_Rewrite_Table): Text column % is missing!', gc.text_geom_column_name;
|
||||
ELSE
|
||||
sql := sql || geom_transform_sql;
|
||||
END IF;
|
||||
|
||||
-- There is at least one true geometry column in here, we'll
|
||||
-- reproject that into the projections we need.
|
||||
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;
|
||||
|
||||
-- Find the column we are going to be working with (the first
|
||||
-- column with type "geometry")
|
||||
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;
|
||||
|
||||
-- The SRID could be undeclared at the table level, but still
|
||||
-- exist in the geometries themselves. We first find our geometry
|
||||
-- column and read the first SRID off it it, if there is a row
|
||||
-- to read.
|
||||
IF FOUND THEN
|
||||
EXECUTE Format('SELECT ST_SRID(%s) AS srid FROM %s LIMIT 1', rec.attname, reloid::text)
|
||||
INTO geom_srid;
|
||||
ELSE
|
||||
geom_srid := 0;
|
||||
END IF;
|
||||
|
||||
-- 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
|
||||
|| ', cartodb.CDB_TransformToWebmercator(' || a.attname || ')::Geometry('
|
||||
|| postgis_typmod_type(a.atttypmod)
|
||||
|| ', 3857) AS '
|
||||
|| const.mercgeomcol,
|
||||
a.attname
|
||||
WITH t AS (
|
||||
SELECT
|
||||
a.attname,
|
||||
postgis_typmod_type(a.atttypmod) AS geomtype,
|
||||
CASE WHEN postgis_typmod_srid(a.atttypmod) = 0 AND srid.srid = 0 THEN 'ST_SetSRID(' ELSE '' END AS missing_srid_start,
|
||||
CASE WHEN postgis_typmod_srid(a.atttypmod) = 0 AND srid.srid = 0 THEN ',4326)' ELSE '' END AS missing_srid_end
|
||||
FROM pg_class c
|
||||
JOIN pg_attribute a ON a.attrelid = c.oid
|
||||
JOIN pg_type t ON a.atttypid = t.oid,
|
||||
( SELECT geom_srid AS srid ) AS srid
|
||||
WHERE c.oid = reloid
|
||||
AND t.typname = 'geometry'
|
||||
AND a.attnum > 0
|
||||
AND NOT a.attisdropped
|
||||
ORDER BY a.attnum
|
||||
LIMIT 1
|
||||
)
|
||||
SELECT ', ST_Transform('
|
||||
|| t.missing_srid_start || t.attname || t.missing_srid_end
|
||||
|| ',4326)::Geometry('
|
||||
|| t.geomtype
|
||||
|| ',4326) AS '
|
||||
|| const.geomcol
|
||||
|| ', cartodb.CDB_TransformToWebmercator('
|
||||
|| t.missing_srid_start || t.attname || t.missing_srid_end
|
||||
|| ')::Geometry('
|
||||
|| t.geomtype
|
||||
|| ',3857) AS '
|
||||
|| const.mercgeomcol,
|
||||
t.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
|
||||
FROM t;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
-- If there are no geometry columns, 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
|
||||
sql := sql || geom_transform_sql;
|
||||
END IF;
|
||||
|
||||
END IF;
|
||||
|
||||
|
||||
END IF;
|
||||
|
||||
-- Add now add all the rest of the columns
|
||||
@@ -1112,7 +1234,7 @@ BEGIN
|
||||
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);
|
||||
sql := Format('CREATE INDEX ON %s USING GIST (%s)', reloid::text, rec.attname);
|
||||
PERFORM _CDB_SQL(sql, '_CDB_Add_Indexes');
|
||||
END LOOP;
|
||||
|
||||
|
||||
@@ -3,11 +3,12 @@ CREATE OR REPLACE FUNCTION CDB_ColumnNames(REGCLASS)
|
||||
RETURNS SETOF information_schema.sql_identifier
|
||||
AS $$
|
||||
|
||||
SELECT column_name
|
||||
FROM information_schema.columns
|
||||
WHERE
|
||||
table_name IN (SELECT CDB_UserTables())
|
||||
AND table_name = '' || $1 || '';
|
||||
SELECT c.column_name
|
||||
FROM information_schema.columns c, pg_class _tn, pg_namespace _sn
|
||||
WHERE table_name = _tn.relname
|
||||
AND table_schema = _sn.nspname
|
||||
AND _tn.oid = $1::oid
|
||||
AND _sn.oid = _tn.relnamespace;
|
||||
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
@@ -3,12 +3,13 @@ CREATE OR REPLACE FUNCTION CDB_ColumnType(REGCLASS, TEXT)
|
||||
RETURNS information_schema.character_data
|
||||
AS $$
|
||||
|
||||
SELECT data_type
|
||||
FROM information_schema.columns
|
||||
WHERE
|
||||
table_name IN (SELECT CDB_UserTables())
|
||||
AND table_name = '' || $1 || ''
|
||||
AND column_name = '' || quote_ident($2) || '';
|
||||
SELECT c.data_type
|
||||
FROM information_schema.columns c, pg_class _tn, pg_namespace _sn
|
||||
WHERE table_name = _tn.relname
|
||||
AND table_schema = _sn.nspname
|
||||
AND column_name = $2
|
||||
AND _tn.oid = $1::oid
|
||||
AND _sn.oid = _tn.relnamespace;
|
||||
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
@@ -41,11 +41,11 @@ BEGIN
|
||||
xpath('//x:Relation-Name/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as x,
|
||||
xpath('//x:Relation-Name/../x:Schema/text()', exp, ARRAY[ARRAY['x', 'http://www.postgresql.org/2009/explain']]) as s
|
||||
)
|
||||
SELECT unnest(x) as p, unnest(s) as sc from inp
|
||||
SELECT unnest(x)::text as p, unnest(s)::text as sc from inp
|
||||
LOOP
|
||||
-- RAISE DEBUG 'tab: %', rec2.p;
|
||||
-- RAISE DEBUG 'sc: %', rec2.sc;
|
||||
tables := array_append(tables, (rec2.sc || '.' || rec2.p));
|
||||
tables := array_append(tables, format('%s.%s', quote_ident(rec2.sc), quote_ident(rec2.p)));
|
||||
END LOOP;
|
||||
|
||||
-- RAISE DEBUG 'Tables: %', tables;
|
||||
|
||||
47
scripts-available/CDB_Stats.sql
Normal file
47
scripts-available/CDB_Stats.sql
Normal file
@@ -0,0 +1,47 @@
|
||||
--
|
||||
-- Calculate basic statistics of a given dataset
|
||||
--
|
||||
-- @param in_array A numeric array of numbers
|
||||
--
|
||||
-- Returns: statistical quantity chosen
|
||||
--
|
||||
-- References: http://www.itl.nist.gov/div898/handbook/eda/section3/eda35b.htm
|
||||
--
|
||||
|
||||
-- Calculate kurtosis
|
||||
CREATE OR REPLACE FUNCTION CDB_Kurtosis ( in_array NUMERIC[] ) RETURNS NUMERIC as $$
|
||||
DECLARE
|
||||
a numeric;
|
||||
c numeric;
|
||||
s numeric;
|
||||
k numeric;
|
||||
BEGIN
|
||||
SELECT AVG(e), COUNT(e)::numeric, stddev(e) INTO a, c, s FROM ( SELECT unnest(in_array) e ) x;
|
||||
|
||||
EXECUTE 'SELECT sum(power($1 - e, 4)) / ( $2 * power($3, 4)) - 3
|
||||
FROM (SELECT unnest($4) e ) x'
|
||||
INTO k
|
||||
USING a, c, s, in_array;
|
||||
|
||||
RETURN k;
|
||||
END;
|
||||
$$ language plpgsql IMMUTABLE;
|
||||
|
||||
-- Calculate skewness
|
||||
CREATE OR REPLACE FUNCTION CDB_Skewness ( in_array NUMERIC[] ) RETURNS NUMERIC as $$
|
||||
DECLARE
|
||||
a numeric;
|
||||
c numeric;
|
||||
s numeric;
|
||||
sk numeric;
|
||||
BEGIN
|
||||
SELECT AVG(e), COUNT(e)::numeric, stddev(e) INTO a, c, s FROM ( SELECT unnest(in_array) e ) x;
|
||||
|
||||
EXECUTE 'SELECT sum(power($1 - e, 3)) / ( $2 * power($3, 3))
|
||||
FROM (SELECT unnest($4) e ) x'
|
||||
INTO sk
|
||||
USING a, c, s, in_array;
|
||||
|
||||
RETURN sk;
|
||||
END;
|
||||
$$ language plpgsql IMMUTABLE;
|
||||
@@ -5,7 +5,6 @@
|
||||
--
|
||||
-- Currently accepted permissions are: 'public', 'private' or 'all'
|
||||
--
|
||||
DROP FUNCTION IF EXISTS cdb_usertables(text);
|
||||
CREATE OR REPLACE FUNCTION CDB_UserTables(perm text DEFAULT 'all')
|
||||
RETURNS SETOF name
|
||||
AS $$
|
||||
|
||||
1
scripts-enabled/CDB_Stats.sql
Symbolic link
1
scripts-enabled/CDB_Stats.sql
Symbolic link
@@ -0,0 +1 @@
|
||||
../scripts-available/CDB_Stats.sql
|
||||
@@ -181,7 +181,31 @@ 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;
|
||||
SELECT cartodb_id FROM t;
|
||||
DROP TABLE t;
|
||||
|
||||
-- table with text geometry column
|
||||
CREATE TABLE t AS SELECT 'SRID=4326;POINT(1 1)'::text AS the_geom, 1::int4 as cartodb_id;
|
||||
SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column');
|
||||
SELECT cartodb_id FROM t;
|
||||
DROP TABLE t;
|
||||
|
||||
-- table with text geometry column, no SRS
|
||||
CREATE TABLE t AS SELECT 'POINT(1 1)'::text AS the_geom, 1::int4 as cartodb_id;
|
||||
SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column, no srs');
|
||||
SELECT cartodb_id FROM t;
|
||||
DROP TABLE t;
|
||||
|
||||
-- table with text geometry column, unusual SRS
|
||||
CREATE TABLE t AS SELECT 'SRID=26910;POINT(1 1)'::text AS the_geom, 1::int4 as cartodb_id;
|
||||
SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column, srs = 26819');
|
||||
SELECT cartodb_id FROM t;
|
||||
DROP TABLE t;
|
||||
|
||||
-- table with text unparseable geometry column
|
||||
CREATE TABLE t AS SELECT 'SRID=26910;PONT(1 1)'::text AS the_geom, 1::int4 as cartodb_id;
|
||||
SELECT CDB_CartodbfyTableCheck('t', 'text the_geom column, unparseable content');
|
||||
SELECT cartodb_id FROM t;
|
||||
DROP TABLE t;
|
||||
|
||||
-- table with existing cartodb_id serial primary key
|
||||
@@ -192,6 +216,15 @@ WHERE c.conrelid = 't'::regclass and a.attrelid = c.conrelid
|
||||
AND c.conkey[1] = a.attnum AND NOT a.attisdropped;
|
||||
DROP TABLE t;
|
||||
|
||||
-- tables can be renamed and there's no index name clashing #123
|
||||
CREATE TABLE original();
|
||||
SELECT CDB_CartodbfyTable('original');
|
||||
ALTER TABLE original RENAME TO original_renamed;
|
||||
CREATE TABLE original();
|
||||
SELECT CDB_CartodbfyTable('original');
|
||||
DROP TABLE original_renamed;
|
||||
DROP TABLE original;
|
||||
|
||||
-- TODO: table with existing custom-triggered the_geom
|
||||
|
||||
DROP FUNCTION CDB_CartodbfyTableCheck(regclass, text);
|
||||
|
||||
@@ -31,9 +31,32 @@ SELECT 1
|
||||
unsequenced cartodb_id cartodbfied fine
|
||||
1
|
||||
DROP TABLE
|
||||
SELECT 1
|
||||
text the_geom column cartodbfied fine
|
||||
1
|
||||
DROP TABLE
|
||||
SELECT 1
|
||||
text the_geom column, no srs cartodbfied fine
|
||||
1
|
||||
DROP TABLE
|
||||
SELECT 1
|
||||
text the_geom column, srs = 26819 cartodbfied fine
|
||||
1
|
||||
DROP TABLE
|
||||
SELECT 1
|
||||
text the_geom column, unparseable content cartodbfied fine
|
||||
1
|
||||
DROP TABLE
|
||||
CREATE TABLE
|
||||
cartodb_id serial primary key cartodbfied fine
|
||||
t_pkey|cartodb_id
|
||||
DROP TABLE
|
||||
CREATE TABLE
|
||||
original
|
||||
ALTER TABLE
|
||||
CREATE TABLE
|
||||
original
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
DROP FUNCTION
|
||||
DROP FUNCTION
|
||||
|
||||
@@ -1,6 +1,9 @@
|
||||
set client_min_messages to error;
|
||||
\set VERBOSITY default
|
||||
|
||||
-- See the dice
|
||||
SELECT setseed(0.5);
|
||||
|
||||
CREATE TABLE big(a int);
|
||||
-- Try the legacy interface
|
||||
-- See https://github.com/CartoDB/cartodb-postgresql/issues/13
|
||||
@@ -18,6 +21,7 @@ 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 setseed(0.9);
|
||||
SELECT CDB_SetUserQuotaInBytes(2);
|
||||
INSERT INTO big VALUES (8193);
|
||||
SELECT CDB_SetUserQuotaInBytes(0);
|
||||
|
||||
@@ -1,4 +1,5 @@
|
||||
SET
|
||||
|
||||
CREATE TABLE
|
||||
CREATE TRIGGER
|
||||
INSERT 0 1
|
||||
@@ -11,6 +12,7 @@ INSERT 0 2048
|
||||
454656
|
||||
909312
|
||||
0
|
||||
|
||||
2
|
||||
ERROR: Quota exceeded by 443.998046875KB
|
||||
0
|
||||
|
||||
16
test/CDB_StatsTest.sql
Normal file
16
test/CDB_StatsTest.sql
Normal file
@@ -0,0 +1,16 @@
|
||||
-- continuous uniform distribution has kurtosis = -6/5, skewness = 0.0
|
||||
-- http://mathworld.wolfram.com/UniformDistribution.html
|
||||
set client_min_messages to ERROR;
|
||||
|
||||
With dist As (
|
||||
SELECT random()::numeric As val
|
||||
FROM generate_series(1,50000) t
|
||||
)
|
||||
|
||||
SELECT
|
||||
-- does random dist values match within 1% of known values
|
||||
abs(CDB_Kurtosis(array_agg(val)) + 1.20) < 1e-2 As kurtosis,
|
||||
abs(CDB_Skewness(array_agg(val)) - 0) < 1e-2 As skewness
|
||||
FROM dist;
|
||||
|
||||
set client_min_messages to NOTICE;
|
||||
3
test/CDB_StatsTest_expect
Normal file
3
test/CDB_StatsTest_expect
Normal file
@@ -0,0 +1,3 @@
|
||||
SET
|
||||
t|t
|
||||
SET
|
||||
@@ -1,4 +1,6 @@
|
||||
SET SCHEMA 'cartodb';
|
||||
\i scripts-available/CDB_Quota.sql
|
||||
\i scripts-available/CDB_TableMetadata.sql
|
||||
\i scripts-available/CDB_ColumnNames.sql
|
||||
\i scripts-available/CDB_ColumnType.sql
|
||||
SET SCHEMA 'public';
|
||||
@@ -178,6 +178,7 @@ function setup() {
|
||||
sql "CREATE SCHEMA cartodb;"
|
||||
sql "GRANT USAGE ON SCHEMA cartodb TO public;"
|
||||
sql "CREATE EXTENSION postgis;"
|
||||
sql "CREATE EXTENSION plpythonu;"
|
||||
|
||||
log_info "########################### BOOTSTRAP ###########################"
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_Organizations.sql
|
||||
@@ -227,7 +228,12 @@ function run_tests() {
|
||||
local TESTS
|
||||
if [[ $# -ge 1 ]]
|
||||
then
|
||||
TESTS="$@"
|
||||
if [[ $# -eq 1 ]]
|
||||
then
|
||||
TESTS=`cat $0 | grep -o "$1[^\(]*"`
|
||||
else
|
||||
TESTS="$@"
|
||||
fi
|
||||
else
|
||||
TESTS=`cat $0 | perl -n -e'/function (test.*)\(\)/ && print "$1\n"'`
|
||||
fi
|
||||
@@ -337,6 +343,92 @@ function test_cdb_tablemetadatatouch_fails_from_user_without_permission() {
|
||||
sql postgres "REVOKE ALL ON CDB_TableMetadata FROM cdb_testmember_1;"
|
||||
}
|
||||
|
||||
function test_cdb_column_names() {
|
||||
sql cdb_testmember_1 'CREATE TABLE cdb_testmember_1.table_cnames(c int, a int, r int, t int, o int);'
|
||||
sql cdb_testmember_2 'CREATE TABLE cdb_testmember_2.table_cnames(d int, b int);'
|
||||
|
||||
sql cdb_testmember_1 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('table_cnames') c) as s" should "carto"
|
||||
sql cdb_testmember_2 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('table_cnames') c) as s" should "db"
|
||||
|
||||
sql postgres "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames'::regclass) c) as s" should "carto"
|
||||
sql postgres "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_2.table_cnames') c) as s" should "db"
|
||||
|
||||
# Using schema from owner
|
||||
sql cdb_testmember_1 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames') c) as s" should "carto"
|
||||
|
||||
## it's not possible to get column names from a table where you don't have permissions
|
||||
sql cdb_testmember_2 "SELECT string_agg(c,'') from (SELECT cartodb.CDB_ColumnNames('cdb_testmember_1.table_cnames') c) as s" fails
|
||||
|
||||
sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.table_cnames'
|
||||
sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.table_cnames'
|
||||
}
|
||||
|
||||
function test_cdb_column_type() {
|
||||
sql cdb_testmember_1 'CREATE TABLE cdb_testmember_1.table_ctype(c int, a int, r int, t int, o int);'
|
||||
sql cdb_testmember_2 'CREATE TABLE cdb_testmember_2.table_ctype(c text, a text, r text, t text, o text);'
|
||||
|
||||
sql cdb_testmember_1 "SELECT cartodb.CDB_ColumnType('table_ctype', 'c')" should "integer"
|
||||
sql cdb_testmember_2 "SELECT cartodb.CDB_ColumnType('table_ctype', 'c')" should "text"
|
||||
|
||||
sql postgres "SELECT cartodb.CDB_ColumnType('cdb_testmember_1.table_ctype', 'c')" should "integer"
|
||||
sql postgres "SELECT cartodb.CDB_ColumnType('cdb_testmember_2.table_ctype', 'c')" should "text"
|
||||
|
||||
sql cdb_testmember_1 'DROP TABLE cdb_testmember_1.table_ctype'
|
||||
sql cdb_testmember_2 'DROP TABLE cdb_testmember_2.table_ctype'
|
||||
}
|
||||
|
||||
function test_cdb_querytables_schema_and_table_names_with_dots() {
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
|
||||
|
||||
sql postgres 'CREATE SCHEMA "foo.bar";'
|
||||
sql postgres 'CREATE TABLE "foo.bar"."c.a.r.t.o.d.b" (a int);'
|
||||
sql postgres 'INSERT INTO "foo.bar"."c.a.r.t.o.d.b" values (1);'
|
||||
sql postgres 'SELECT a FROM "foo.bar"."c.a.r.t.o.d.b";' should 1
|
||||
|
||||
sql postgres 'SELECT CDB_QueryTablesText($q$select * from "foo.bar"."c.a.r.t.o.d.b"$q$);' should '{"\"foo.bar\".\"c.a.r.t.o.d.b\""}'
|
||||
sql postgres 'SELECT CDB_QueryTables($q$select * from "foo.bar"."c.a.r.t.o.d.b"$q$);' should '{"\"foo.bar\".\"c.a.r.t.o.d.b\""}'
|
||||
|
||||
sql postgres 'DROP TABLE "foo.bar"."c.a.r.t.o.d.b";'
|
||||
sql postgres 'DROP SCHEMA "foo.bar";'
|
||||
}
|
||||
|
||||
function test_cdb_querytables_table_name_with_dots() {
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
|
||||
|
||||
sql postgres 'CREATE TABLE "w.a.d.u.s" (a int);';
|
||||
|
||||
sql postgres 'SELECT CDB_QueryTablesText($q$select * from "w.a.d.u.s"$q$);' should '{"public.\"w.a.d.u.s\""}'
|
||||
sql postgres 'SELECT CDB_QueryTables($q$select * from "w.a.d.u.s"$q$);' should '{"public.\"w.a.d.u.s\""}'
|
||||
|
||||
sql postgres 'DROP TABLE "w.a.d.u.s";';
|
||||
}
|
||||
|
||||
function test_cdb_querytables_happy_cases() {
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql
|
||||
${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql
|
||||
|
||||
sql postgres 'CREATE TABLE wadus (a int);';
|
||||
sql postgres 'CREATE TABLE "FOOBAR" (a int);';
|
||||
sql postgres 'CREATE SCHEMA foo;'
|
||||
sql postgres 'CREATE TABLE foo.wadus (a int);';
|
||||
|
||||
## See how it does NOT quote anything here
|
||||
sql postgres 'SELECT CDB_QueryTablesText($q$select * from wadus$q$);' should '{public.wadus}'
|
||||
sql postgres 'SELECT CDB_QueryTablesText($q$select * from foo.wadus$q$);' should '{foo.wadus}'
|
||||
sql postgres 'SELECT CDB_QueryTables($q$select * from wadus$q$);' should '{public.wadus}'
|
||||
sql postgres 'SELECT CDB_QueryTables($q$select * from foo.wadus$q$);' should '{foo.wadus}'
|
||||
|
||||
## But it quotes when it's needed even if table name has no dots but was created with quotes
|
||||
sql postgres 'SELECT CDB_QueryTablesText($q$select * from "FOOBAR"$q$);' should '{"public.\"FOOBAR\""}'
|
||||
|
||||
sql postgres 'DROP TABLE wadus;'
|
||||
sql postgres 'DROP TABLE "FOOBAR";'
|
||||
sql postgres 'DROP TABLE foo.wadus;'
|
||||
sql postgres 'DROP SCHEMA foo;'
|
||||
}
|
||||
|
||||
#################################################### TESTS END HERE ####################################################
|
||||
|
||||
run_tests $@
|
||||
|
||||
Reference in New Issue
Block a user