Import cartodb/lib/sql/test, add search_path tweaker

This commit is contained in:
Sandro Santilli 2014-05-05 18:48:48 +02:00
parent 5e28417b3d
commit 0960276046
30 changed files with 556 additions and 22 deletions

View File

@ -9,7 +9,9 @@ CDBSCRIPTS = \
DATA_built = $(EXTENSION)--$(EXTVERSION).sql DATA_built = $(EXTENSION)--$(EXTVERSION).sql
DOCS = README.md DOCS = README.md
REGRESS = test_ddl_triggers REGRESS_EXTENSION = test_ddl_triggers
REGRESS_LEGACY = test/CDB_DigitSeparatorTest
REGRESS = $(REGRESS_EXTENSION)
PG_CONFIG = pg_config PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs) PGXS := $(shell $(PG_CONFIG) --pgxs)

View File

@ -183,24 +183,3 @@ CREATE OR REPLACE FUNCTION cartodb.cdb_enable_ddl_hooks() returns void AS $$
$$ LANGUAGE sql; $$ LANGUAGE sql;
SELECT cartodb.cdb_enable_ddl_hooks(); SELECT cartodb.cdb_enable_ddl_hooks();
---- Make sure 'cartodb' is in database search path ?
--DO
--$$
--DECLARE
-- var_result text;
-- var_cur_search_path text;
--BEGIN
-- SELECT reset_val INTO var_cur_search_path
-- FROM pg_settings WHERE name = 'search_path';
--
-- IF var_cur_search_path LIKE '%cartodb%' THEN
-- RAISE DEBUG '"cartodb" already in database search_path';
-- ELSE
-- EXECUTE 'ALTER DATABASE ' || quote_ident(current_database()) ||
-- ' SET search_path = ' || var_cur_search_path || ', "cartodb"';
-- RAISE DEBUG '"cartodb" has been added to end of database search_path';
-- END IF;
--END
--$$ LANGUAGE 'plpgsql';

View File

@ -0,0 +1,24 @@
---- Make sure 'cartodb' is in database search path
DO
$$
DECLARE
var_result text;
var_cur_search_path text;
BEGIN
SELECT reset_val INTO var_cur_search_path
FROM pg_settings WHERE name = 'search_path';
IF var_cur_search_path LIKE '%cartodb%' THEN
RAISE DEBUG '"cartodb" already in database search_path';
ELSE
var_cur_search_path := var_cur_search_path || ', "cartodb"';
EXECUTE 'ALTER DATABASE ' || quote_ident(current_database()) ||
' SET search_path = ' || var_cur_search_path;
RAISE DEBUG '"cartodb" has been added to end of database search_path';
END IF;
-- Reset search_path
EXECUTE 'SET search_path = ' || var_cur_search_path;
END
$$ LANGUAGE 'plpgsql';

View File

@ -0,0 +1 @@
../scripts-available/CDB_SearchPath.sql

1
sql/test Symbolic link
View File

@ -0,0 +1 @@
../test

View File

@ -0,0 +1,173 @@
SET client_min_messages TO error;
\set VERBOSITY terse;
CREATE OR REPLACE FUNCTION CDB_CartodbfyTableCheck(tabname regclass, label text)
RETURNS text AS
$$
DECLARE
sql TEXT;
id INTEGER;
rec RECORD;
lag INTERVAL;
tmp INTEGER;
ogc_geom geometry_columns; -- old the_geom record in geometry_columns
ogc_merc geometry_columns; -- old the_geom_webmercator record in geometry_columns
BEGIN
-- Save current constraints on geometry columns, if any
ogc_geom = ('','','','',0,0,'GEOMETRY');
ogc_merc = ogc_geom;
sql := 'SELECT gc.* FROM geometry_columns gc, pg_class c, pg_namespace n '
|| 'WHERE c.oid = ' || tabname::oid || ' AND n.oid = c.relnamespace'
|| ' AND gc.f_table_schema = n.nspname AND gc.f_table_name = c.relname'
|| ' AND gc.f_geometry_column IN ( ' || quote_literal('the_geom')
|| ',' || quote_literal('the_geom_webmercator') || ')';
FOR rec IN EXECUTE sql LOOP
IF rec.f_geometry_column = 'the_geom' THEN
ogc_geom := rec;
ELSE
ogc_merc := rec;
END IF;
END LOOP;
PERFORM CDB_CartodbfyTable(tabname);
sql := 'INSERT INTO ' || tabname::text || '(the_geom) values ( CDB_LatLng(2,1) ) RETURNING cartodb_id';
EXECUTE sql INTO STRICT id;
sql := 'SELECT created_at,updated_at,the_geom_webmercator FROM '
|| tabname::text || ' WHERE cartodb_id = ' || id;
EXECUTE sql INTO STRICT rec;
-- Check created_at and updated_at at creation time
lag = rec.created_at - now();
IF lag > '1 second' THEN
RAISE EXCEPTION 'created_at not defaulting to now() after insert [ valued % ago ]', lag;
END IF;
lag = rec.updated_at - now();
IF lag > '1 second' THEN
RAISE EXCEPTION 'updated_at not defaulting to now() after insert [ valued % ago ]', lag;
END IF;
-- Check the_geom_webmercator trigger
IF round(st_x(rec.the_geom_webmercator)) != 111319 THEN
RAISE EXCEPTION 'the_geom_webmercator X is % (expecting 111319)', round(st_x(rec.the_geom_webmercator));
END IF;
IF round(st_y(rec.the_geom_webmercator)) != 222684 THEN
RAISE EXCEPTION 'the_geom_webmercator Y is % (expecting 222684)', round(st_y(rec.the_geom_webmercator));
END IF;
-- Check CDB_TableMetadata entry
sql := 'SELECT * FROM CDB_TableMetadata WHERE tabname = ' || tabname::oid;
EXECUTE sql INTO STRICT rec;
lag = rec.updated_at - now();
IF lag > '1 second' THEN
RAISE EXCEPTION 'updated_at in CDB_TableMetadata not set to now() after insert [ valued % ago ]', lag;
END IF;
-- Check geometry_columns entries
tmp := 0;
FOR rec IN
SELECT
CASE WHEN gc.f_geometry_column = 'the_geom' THEN 4326
ELSE 3857 END as expsrid,
CASE WHEN gc.f_geometry_column = 'the_geom' THEN ogc_geom.type
ELSE ogc_merc.type END as exptype, gc.*
FROM geometry_columns gc, pg_class c, pg_namespace n
WHERE c.oid = tabname::oid AND n.oid = c.relnamespace
AND gc.f_table_schema = n.nspname AND gc.f_table_name = c.relname
AND gc.f_geometry_column IN ( 'the_geom', 'the_geom_webmercator')
LOOP
tmp := tmp + 1;
-- Check SRID constraint
IF rec.srid != rec.expsrid THEN
RAISE EXCEPTION 'SRID of % in geometry_columns is %, expected %',
rec.f_geometry_column, rec.srid, rec.expsrid;
END IF;
-- Check TYPE constraint didn't change
IF rec.type != rec.exptype THEN
RAISE EXCEPTION 'type of % in geometry_columns is %, expected %',
rec.f_geometry_column, rec.type, rec.exptype;
END IF;
-- check coord_dimension ?
END LOOP;
IF tmp != 2 THEN
RAISE EXCEPTION '% entries found for table % in geometry_columns, expected 2', tmp, tabname;
END IF;
-- Check GiST index
sql := 'SELECT a.attname, count(ri.relname) FROM'
|| ' pg_index i, pg_class c, pg_class ri, pg_attribute a, pg_opclass o'
|| ' WHERE i.indrelid = c.oid AND ri.oid = i.indexrelid'
|| ' AND a.attrelid = ri.oid AND o.oid = i.indclass[0]'
|| ' AND a.attname IN ( ' || quote_literal('the_geom')
|| ',' || quote_literal('the_geom_webmercator') || ')'
|| ' AND ri.relnatts = 1 AND o.opcname = '
|| quote_literal('gist_geometry_ops_2d')
|| ' AND c.oid = ' || tabname::oid
|| ' GROUP BY a.attname';
RAISE NOTICE 'sql: %', sql;
EXECUTE sql;
GET DIAGNOSTICS tmp = ROW_COUNT;
IF tmp != 2 THEN
RAISE EXCEPTION '% gist indices found on the_geom and the_geom_webmercator, expected 2', tmp;
END IF;
-- Check null constraint on cartodb_id, created_at, updated_at
SELECT count(*) FROM pg_attribute a, pg_class c WHERE c.oid = tabname::oid
AND a.attrelid = c.oid AND NOT a.attisdropped AND a.attname in
( 'cartodb_id', 'created_at', 'updated_at' )
AND NOT a.attnotnull INTO strict tmp;
IF tmp > 0 THEN
RAISE EXCEPTION 'cartodb_id or created_at or updated_at are missing not-null constraint';
END IF;
-- Cleanup
sql := 'DELETE FROM ' || tabname::text || ' WHERE cartodb_id = ' || id;
EXECUTE sql;
RETURN label || ' cartodbfied fine';
END;
$$
LANGUAGE 'plpgsql';
-- table with single non-geometrical column
CREATE TABLE t AS SELECT 1::int as a;
SELECT CDB_CartodbfyTableCheck('t', 'single non-geometrical column');
DROP TABLE t;
-- table with existing srid-unconstrained (but type-constrained) the_geom
CREATE TABLE t AS SELECT ST_SetSRID(ST_MakePoint(0,0),4326)::geometry(point) as the_geom;
SELECT CDB_CartodbfyTableCheck('t', 'srid-unconstrained the_geom');
DROP TABLE t;
-- table with mixed-srid the_geom values
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;
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;
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;
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();
SELECT CDB_CartodbfyTableCheck('t', 'trigger-protected the_geom');
SELECT 'extent',ST_Extent(ST_SnapToGrid(the_geom,0.1)) FROM t;
DROP TABLE t;
-- TODO: table with existing custom-triggered the_geom
DROP FUNCTION CDB_CartodbfyTableCheck(regclass, text);

View File

@ -0,0 +1,26 @@
SET
CREATE FUNCTION
SELECT 1
single non-geometrical column cartodbfied fine
DROP TABLE
SELECT 1
srid-unconstrained the_geom cartodbfied fine
DROP TABLE
SELECT 2
mixed-srid the_geom cartodbfied fine
extent|BOX(-1 -1,0 0)
DROP TABLE
SELECT 1
wrong srid-constrained the_geom cartodbfied fine
extent|BOX(1 1,2 2)|BOX(111319 111325,222639 222684)
DROP TABLE
SELECT 1
wrong srid-constrained the_geom_webmercator cartodbfied fine
extent|BOX(1 1,2 2)
DROP TABLE
SELECT 1
CREATE TRIGGER
trigger-protected the_geom cartodbfied fine
extent|BOX(1 1,2 2)
DROP TABLE
DROP FUNCTION

View File

@ -0,0 +1,39 @@
BEGIN;
CREATE TEMP TABLE "_CDB_DigitSeparatorTest" (
none text,
only_com_dec text,
only_dot_dec text,
only_com_tho text,
only_dot_tho text,
both_com_dec text,
both_dot_dec text,
"only_com_AMB" text,
"only_dot_AMB" text
);
COPY "_CDB_DigitSeparatorTest" FROM STDIN;
123456 123,1235 123.12345 1,234,231 1.234.234 1.234,23 1,234.23 1,123 1.123
123456 123,12 123.12 231 234 1.121.234,230 3,111,234.230 123,123 123.123
123456 123,12 123.12 231 234 1.121.234,2 3,111,234.230 123,123 123.123
\.
SELECT 'none', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'none');
SELECT 'only_com_dec', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_dec');
SELECT 'only_dot_dec', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_dec');
SELECT 'only_com_tho', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_tho');
SELECT 'only_dot_tho', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_tho');
SELECT 'both_com_dec', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'both_com_dec');
SELECT 'both_dot_dec', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'both_dot_dec');
SELECT 'only_com_AMB', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_com_AMB');
SELECT 'only_dot_AMB', * FROM
CDB_DigitSeparator('"_CDB_DigitSeparatorTest"'::regclass, 'only_dot_AMB');
DROP TABLE "_CDB_DigitSeparatorTest";
COMMIT;

View File

@ -0,0 +1,13 @@
BEGIN
CREATE TABLE
none||
only_com_dec|.|,
only_dot_dec|,|.
only_com_tho|,|.
only_dot_tho|.|,
both_com_dec|.|,
both_dot_dec|,|.
only_com_AMB||
only_dot_AMB||
DROP TABLE
COMMIT

View File

@ -0,0 +1,5 @@
WITH data AS (
SELECT array_agg(x) x FROM generate_series(1,100) x
WHERE x % 5 != 0 AND x % 7 != 0
)
SELECT round(unnest(CDB_HeadsTailsBins(x, 7)),2) FROM data

View File

@ -0,0 +1,7 @@
49.56
74.44
87.50
93.50
96.50
98.00
99.00

47
test/CDB_HexagonTest.sql Normal file
View File

@ -0,0 +1,47 @@
-- Check correctness of an hexagons grid
--
-- Cells must have no overlaps and have a number of
-- intersections with other cells between 2 and 6
--
WITH
params AS ( SELECT ST_MakeEnvelope(10, 10, 20, 20) as env, 2 as radius ),
grid AS ( SELECT CDB_HexagonGrid(env, radius) AS cell from params),
igrid AS ( SELECT row_number() over (), cell from grid )
SELECT count(row_number) as r1, sum(st_npoints(cell)) as r2, 'count / npoints' as err
FROM igrid g1
UNION ALL
SELECT g1.row_number as r1, g2.row_number as r2, 'overlap' as err
FROM igrid g1, igrid g2
WHERE g2.row_number > g1.row_number AND
ST_Overlaps(g1.cell, g2.cell)
UNION ALL
SELECT g1.row_number, count(g2.row_number) as r2, 'n intersections' as err
FROM igrid g1, igrid g2
WHERE g1.row_number != g2.row_number AND
ST_Intersects(g1.cell, g2.cell)
GROUP BY g1.row_number
HAVING count(g2.row_number) > 6 OR count(g2.row_number) < 2
UNION ALL
SELECT g1.row_number, null::integer, 'centroid out of extent' as err
FROM igrid g1, params
WHERE NOT ST_Intersects(ST_Centroid(g1.cell), params.env)
;
-- Check robustness of HexagonGrid generation
WITH
params AS ( SELECT
ST_MakeEnvelope(-20037508.5,20037507,-20037508,20037507.5) as env,
0.002 as radius ),
grid AS ( SELECT CDB_HexagonGrid(env, radius) AS cell from params)
SELECT '#160', count(cell) > 23000 from grid;

View File

@ -0,0 +1,2 @@
9|63|count / npoints
#160|t

View File

@ -0,0 +1,5 @@
WITH data AS (
SELECT array_agg(x) x FROM generate_series(1,100) x
WHERE x % 5 != 0 AND x % 7 != 0
)
SELECT unnest(CDB_JenksBins(x, 7)) FROM data

View File

@ -0,0 +1,7 @@
13
29
43
57
71
83
99

View File

@ -0,0 +1,5 @@
WITH data AS (
SELECT array_agg(x) x FROM generate_series(1,100) x
WHERE x % 5 != 0 AND x % 7 != 0
)
SELECT unnest(CDB_QuantileBins(x, 7)) FROM data

View File

@ -0,0 +1,7 @@
16
29
43
57
71
83
99

View File

@ -0,0 +1,28 @@
WITH q AS ( SELECT CDB_QueryStatements('
SELECT * FROM geometry_columns;
') as statement )
SELECT '1', row_number() over (), statement FROM q;
WITH q AS ( SELECT CDB_QueryStatements('
SELECT * FROM geometry_columns
') as statement )
SELECT '2', row_number() over (), statement FROM q;
WITH q AS ( SELECT CDB_QueryStatements('
;;;SELECT * FROM geometry_columns
') as statement )
SELECT '3', row_number() over (), statement FROM q;
WITH q AS ( SELECT CDB_QueryStatements($the_param$
CREATE table "my'tab;le" ("$" int);
SELECT '1','$$', '$hello$', "$" FROM "my'tab;le";
CREATE function "hi'there" ("'" text default '$') returns void as $h$ declare a int; b text; begin b='hi'; return; end; $h$ language 'plpgsql';
SELECT 5;
$the_param$) as statement )
SELECT '4', row_number() over (), statement FROM q;
WITH q AS ( SELECT CDB_QueryStatements($the_param$
INSER INTO "my''""t" values ('''','""'';;');
SELECT $qu;oted$ hi $qu;oted$;
$the_param$) as statement )
SELECT '5', row_number() over (), statement FROM q;

View File

@ -0,0 +1,9 @@
1|1|SELECT * FROM geometry_columns
2|1|SELECT * FROM geometry_columns
3|1|SELECT * FROM geometry_columns
4|1|CREATE table "my'tab;le" ("$" int)
4|2|SELECT '1','$$', '$hello$', "$" FROM "my'tab;le"
4|3|CREATE function "hi'there" ("'" text default '$') returns void as $h$ declare a int; b text; begin b='hi'; return; end; $h$ language 'plpgsql'
4|4|SELECT 5
5|1|INSER INTO "my''""t" values ('''','""'';;')
5|2|SELECT $qu;oted$ hi $qu;oted$

View File

@ -0,0 +1,27 @@
WITH inp AS ( select 'SELECT * FROM geometry_columns'::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select 'SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)'::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select $quote$CREATE table "my'tab;le" as select 1$quote$::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select 'SELECT a.oid, b.oid FROM pg_class a, pg_class b'::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select 'SELECT 1 as col1; select 2 as col2'::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select 'select 1 from nonexistant'::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select 'begin; select * from pg_class; commit;'::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select 'create table test (a int); insert into test values (1); select * from test;'::text as q )
SELECT q, CDB_QueryTables(q) from inp;
WITH inp AS ( select 'WITH a AS (select * from pg_class) select * from a'::text as q )
SELECT q, CDB_QueryTables(q) from inp;

View File

@ -0,0 +1,11 @@
SELECT * FROM geometry_columns|{pg_attribute,pg_class,pg_namespace,pg_type}
SELECT a.attname FROM pg_class c JOIN pg_attribute a on (a.attrelid = c.oid)|{pg_attribute,pg_class}
CREATE table "my'tab;le" as select 1|{}
SELECT a.oid, b.oid FROM pg_class a, pg_class b|{pg_class}
SELECT 1 as col1; select 2 as col2|{}
WARNING: CDB_QueryTables cannot explain query: select 1 from nonexistant (42P01: relation "nonexistant" does not exist)
ERROR: relation "nonexistant" does not exist
begin; select * from pg_class; commit;|{pg_class}
WARNING: CDB_QueryTables cannot explain query: select * from test (42P01: relation "test" does not exist)
ERROR: relation "test" does not exist
WITH a AS (select * from pg_class) select * from a|{pg_class}

View File

@ -0,0 +1,28 @@
BEGIN;
SET client_min_messages TO error;
-- Run psql with -tA switches and expect
-- CDB_TransformToWebmercatorTest_expect
select '1', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;LINESTRING(90 90, 0 80)'), 1));
select '2', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;LINESTRING(90 90, 0 90)'), 1));
select '3', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;POINT(0 90)'), 1));
select '4', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;MULTIPOINT(10 3, 0 90, 0 4)'), 1));
select '5', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;MULTIPOINT(10 3)'), 1));
select '6', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;MULTILINESTRING((90 90, 0 90),(0 4, -4 5))'), 1));
select '7', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;POINT(5 3)'), 1));
-- See https://github.com/Vizzuality/cartodb/issues/901
select '8', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;POLYGON((100 0, -100 -100, 100 -100, -100 0, 100 00))'), 1));
-- See https://github.com/Vizzuality/cartodb/issues/931
select '9', CDB_TransformToWebmercator(
'0106000020E61000000100000001030000000100000007000000010000000000F87F9CDFD01E32095341010000000000F87F193B6F0A30095341010000000000F87FA10FBF4C1D095341010000000000F87F38E258111C095341010000000000F87F5196BAFF17095341010000000000F87F4F0550911B095341010000000000F87F9CDFD01E32095341'::geometry);
-- Already in webmercator, doun't touch, even if out of valid bounds
select '10', ST_AsEWKT(CDB_TransformToWebmercator('SRID=3857;POINT(-20037510 -30240972)'::geometry));
END;

View File

@ -0,0 +1,13 @@
BEGIN
SET
1|SRID=3857;LINESTRING(9016879 30240972,0 15538711)
2|
3|
4|SRID=3857;MULTIPOINT(0 445640,1113195 334111)
5|SRID=3857;MULTIPOINT(1113195 334111)
6|SRID=3857;MULTILINESTRING((0 445640,-445278 557305))
7|SRID=3857;POINT(556597 334111)
8|SRID=3857;MULTIPOLYGON(((0 -6446276,8682920 -30240972,-8682920 -30240972,0 -6446276)),((11131949 0,0 -6446276,-11131949 0,11131949 0)))
9|
10|SRID=3857;POINT(-20037510 -30240972)
COMMIT

11
test/CDB_UserTables.sql Normal file
View File

@ -0,0 +1,11 @@
create table pub(a int);
create table prv(a int);
GRANT SELECT ON TABLE pub TO publicuser;
REVOKE SELECT ON TABLE prv FROM publicuser;
SELECT CDB_UserTables() ORDER BY 1;
SELECT 'all',CDB_UserTables('all') ORDER BY 2;
SELECT 'public',CDB_UserTables('public') ORDER BY 2;
SELECT 'private',CDB_UserTables('private') ORDER BY 2;
SELECT '--unsupported--',CDB_UserTables('--unsupported--') ORDER BY 2;
drop table pub;
drop table prv;

View File

@ -0,0 +1,12 @@
CREATE TABLE
CREATE TABLE
GRANT
REVOKE
prv
pub
all|prv
all|pub
public|pub
private|prv
DROP TABLE
DROP TABLE

View File

@ -0,0 +1,9 @@
WITH zoom AS ( select generate_series(0,2) as Z ),
range AS ( select z, generate_series(0, pow(2,z)::int-1) as r FROM zoom),
inp AS ( select z0.z, r1.r as x, r2.r as y FROM zoom z0, range r1, range r2 WHERE z0.z = r1.z and r1.z = r2.z ),
ext AS ( select x,y,z,CDB_XYZ_Extent(x,y,z) as g from inp )
select X::text || ',' || Y::text || ',' || Z::text as xyz,
st_xmin(g), st_xmax(g), st_ymin(g), st_ymax(g)
from ext;

View File

@ -0,0 +1,21 @@
0,0,0|-20037508.5|20037508.5|-20037508.5|20037508.5
0,0,1|-20037508.5|0|0|20037508.5
0,1,1|-20037508.5|0|-20037508.5|0
1,0,1|0|20037508.5|0|20037508.5
1,1,1|0|20037508.5|-20037508.5|0
0,0,2|-20037508.5|-10018754.25|10018754.25|20037508.5
0,1,2|-20037508.5|-10018754.25|0|10018754.25
0,2,2|-20037508.5|-10018754.25|-10018754.25|0
0,3,2|-20037508.5|-10018754.25|-20037508.5|-10018754.25
1,0,2|-10018754.25|0|10018754.25|20037508.5
1,1,2|-10018754.25|0|0|10018754.25
1,2,2|-10018754.25|0|-10018754.25|0
1,3,2|-10018754.25|0|-20037508.5|-10018754.25
2,0,2|0|10018754.25|10018754.25|20037508.5
2,1,2|0|10018754.25|0|10018754.25
2,2,2|0|10018754.25|-10018754.25|0
2,3,2|0|10018754.25|-20037508.5|-10018754.25
3,0,2|10018754.25|20037508.5|10018754.25|20037508.5
3,1,2|10018754.25|20037508.5|0|10018754.25
3,2,2|10018754.25|20037508.5|-10018754.25|0
3,3,2|10018754.25|20037508.5|-20037508.5|-10018754.25

View File

@ -0,0 +1,6 @@
-- 25690 cells covering full webmercator extent
-- real 0m9.448s -- as of e0e76843f785a420c277a6fb2f762601570ffb98
-- real 0m0.243s -- as of 50c487b83837e4d5216fcc19d637dd8db6baa44a
SELECT count(*) FROM (
SELECT CDB_HexagonGrid(ST_MakeEnvelope(-20194051, -20194051, 20194051, 20194051), 156543) ) f;

View File

@ -0,0 +1,16 @@
-- Run psql with -tA switches and expect
-- CDB_TransformToWebmercatorTest_expect
select '1', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;LINESTRING(90 90, 0 80)'), 1));
select '2', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;LINESTRING(90 90, 0 90)'), 1));
select '3', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;POINT(0 90)'), 1));
select '4', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;MULTIPOINT(10 3, 0 90, 0 4)'), 1));
select '5', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;MULTIPOINT(10 3)'), 1));
select '6', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;MULTILINESTRING((90 90, 0 90),(0 4, -4 5))'), 1));
select '7', ST_AsEWKT(ST_SnapToGrid(CDB_TransformToWebmercator(
'SRID=4326;POINT(5 3)'), 1));