Compare commits
24 Commits
| Author | SHA1 | Date | |
|---|---|---|---|
|
|
58fd5d4060 | ||
|
|
a2a1ff6ae8 | ||
|
|
326aae4edb | ||
|
|
2a30eb2fd3 | ||
|
|
0b3ad5e569 | ||
|
|
aa302c237d | ||
|
|
9526f0448f | ||
|
|
3399f2b9a5 | ||
|
|
803b3671d0 | ||
|
|
c3fada29a8 | ||
|
|
86e5f6d317 | ||
|
|
f5f59be5b0 | ||
|
|
d99dc394c2 | ||
|
|
8d7860dc7a | ||
|
|
b5427c65c8 | ||
|
|
8f1435c049 | ||
|
|
8302f89413 | ||
|
|
e9050178a8 | ||
|
|
3e34ca4654 | ||
|
|
a067cc7da1 | ||
|
|
2c43943df6 | ||
|
|
417cbe7902 | ||
|
|
9a73703954 | ||
|
|
36ac831bd1 |
5
Makefile
5
Makefile
@@ -1,7 +1,7 @@
|
||||
# cartodb/Makefile
|
||||
|
||||
EXTENSION = cartodb
|
||||
EXTVERSION = 0.16.1
|
||||
EXTVERSION = 0.16.4
|
||||
|
||||
SED = sed
|
||||
|
||||
@@ -68,6 +68,9 @@ UPGRADABLE = \
|
||||
0.15.1 \
|
||||
0.16.0 \
|
||||
0.16.1 \
|
||||
0.16.2 \
|
||||
0.16.3 \
|
||||
0.16.4 \
|
||||
$(EXTVERSION)dev \
|
||||
$(EXTVERSION)next \
|
||||
$(END)
|
||||
|
||||
28
NEWS.md
28
NEWS.md
@@ -1,3 +1,30 @@
|
||||
0.16.4 (2016-05-27)
|
||||
-------------------
|
||||
|
||||
* Change CDB_ZoomFromScale() to use a formula and raise
|
||||
maximum overview level from 23 to 29.
|
||||
[#259](https://github.com/CartoDB/cartodb-postgresql/pull/259)
|
||||
|
||||
* Fix bug in overview creating causing it to fail when `x` or
|
||||
`y` columns exist with non-integer type. Prevent also
|
||||
potential integer overflows limiting maximum overview level
|
||||
to 23.
|
||||
[#258](https://github.com/CartoDB/cartodb-postgresql/pull/258)
|
||||
|
||||
|
||||
0.16.3 (2016-05-09)
|
||||
-------------------
|
||||
|
||||
* Fix overview creation problem for organization users
|
||||
with names that require quoting:
|
||||
[#253](https://github.com/CartoDB/cartodb-postgresql/pull/253)
|
||||
|
||||
0.16.2 (2016-04-27)
|
||||
-------------------
|
||||
|
||||
* Use the mode to aggregate category columns in overviews
|
||||
[#246](https://github.com/CartoDB/cartodb-postgresql/pull/246)
|
||||
|
||||
0.16.1 (2016-04-25)
|
||||
-------------------
|
||||
|
||||
@@ -10,6 +37,7 @@
|
||||
* Compute webmercator resolution using full numeric precision
|
||||
[#243](https://github.com/CartoDB/cartodb-postgresql/pull/243)
|
||||
|
||||
|
||||
0.16.0 (2016-04-15)
|
||||
-------------------
|
||||
* Adds table for storing camshaft analysis nodes
|
||||
|
||||
@@ -2,18 +2,25 @@ Overviews are tables that represent a *reduced* version of a dataset intended
|
||||
for efficient rendering at certain zoom levels while preserving the
|
||||
general visual appearance of the complete dataset.
|
||||
|
||||
The *reduction* consists in a fewer number of records
|
||||
The *reduction* consists in havig a fewer number of records
|
||||
(while each overview record may represent an aggregation of multiple records)
|
||||
and/or simplified record geometries.
|
||||
|
||||
Overviews are created through the `CDB_CreateOverviews`.
|
||||
Overviews are created through the `CDB_CreateOverviews` function.
|
||||
The statement timeout may need to be adjusted before using this function,
|
||||
as overview creation for large tables is a time-consuming operation.
|
||||
|
||||
The `CDB_Overviews` function can be used determine what overview tables
|
||||
exist for a given dataset table and which zoom levels correspond to it.
|
||||
|
||||
The `CDB_DropOverviews` remove a dataset's existing overviews.
|
||||
The `CDB_DropOverviews` function removes a dataset's existing overviews.
|
||||
|
||||
To know if overview tables exist for some base table, and to obtain
|
||||
a list of which overview tables are approrpiate for which zoom levels,
|
||||
the `CDB_Overviews` functions can be used.
|
||||
|
||||
The zoom level we're referring here to are those used
|
||||
by the tiler: http://wiki.openstreetmap.org/wiki/Zoom_levels
|
||||
|
||||
### CDB_CreateOverviews
|
||||
|
||||
@@ -51,10 +58,14 @@ CDB_CreateOverviews(table_name, ref_z_strategy, reduction_strategy)
|
||||
#### Tolerance / level of detail
|
||||
|
||||
The level of detail to be representable by each overview layer can
|
||||
be specified as a tolerance in pixels (if different from the default of 2 pixels)
|
||||
be specified as a tolerance in pixels (if different from the default of 1 pixel)
|
||||
with the function `CDB_CreateOverviewsWithToleranceInPixels`
|
||||
which has as a second additional argument the desired tolerance.
|
||||
|
||||
This tolerance defines the maximum deviation in pixels of the overviews
|
||||
geometries with respect to the original geometries when overview tables
|
||||
are used for their intendend zoom level.
|
||||
|
||||
### CDB_Overviews
|
||||
|
||||
Obtain overview metadata for a given table (existing overviews).
|
||||
@@ -79,7 +90,7 @@ SELECT CDB_Overviews(CDB_QueryTablesText('SELECT * FROM table1, table2'));
|
||||
The result of `CDB_Overviews` has three columns:
|
||||
|
||||
| base_table | z | overview_table |
|
||||
|------------+---+----------------|
|
||||
| ---------- | - | -------------- |
|
||||
| table1 | 1 | table1_ov1 |
|
||||
| table1 | 2 | table1_ov2 |
|
||||
| table1 | 4 | table1_ov4 |
|
||||
|
||||
@@ -33,7 +33,7 @@ Additionally, a CartoDB table can contain other columns.
|
||||
|
||||
See the `CartoDB User Table documentation`_
|
||||
|
||||
.. _CartoDB User Table documentation: https://github.com/CartoDB/cartodb-postgresql/blob/master/doc/CartoDB-user-table.md
|
||||
.. _CartoDB User Table documentation: https://github.com/CartoDB/cartodb-postgresql/blob/master/doc/CartoDB-user-table.rst
|
||||
for further information.
|
||||
|
||||
High level requirements
|
||||
|
||||
@@ -1,3 +1,29 @@
|
||||
-- Maximum zoom level for which overviews may be created
|
||||
CREATE OR REPLACE FUNCTION _CDB_MaxOverviewLevel()
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Zoom level will be limited so that both tile coordinates
|
||||
-- and gridding coordinates within a tile up to 1px
|
||||
-- (i.e. tile coordinates / 256)
|
||||
-- can be stored in a 32-bit signed integer.
|
||||
-- We have 31 bits por positive numbers
|
||||
-- For zoom level Z coordinates range from 0 to 2^Z-1, so they
|
||||
-- need Z bits, and need 8 bits more to address pixels within a tile
|
||||
-- (gridding), so we'll limit Z to a maximum of 31 - 8
|
||||
RETURN 23;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL IMMUTABLE;
|
||||
|
||||
-- Maximum zoom level usable with integer coordinates
|
||||
CREATE OR REPLACE FUNCTION _CDB_MaxZoomLevel()
|
||||
RETURNS INTEGER
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN 31;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL IMMUTABLE;
|
||||
|
||||
-- Information about tables in a schema.
|
||||
-- If the schema name parameter is NULL, then tables from all schemas
|
||||
-- that may contain user tables are returned.
|
||||
@@ -88,6 +114,26 @@ AS $$
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL IMMUTABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION _CDB_OverviewBaseTable(overview_table REGCLASS)
|
||||
RETURNS REGCLASS
|
||||
AS $$
|
||||
DECLARE
|
||||
table_name TEXT;
|
||||
schema_name TEXT;
|
||||
base_name TEXT;
|
||||
base_table REGCLASS;
|
||||
BEGIN
|
||||
SELECT * FROM _cdb_split_table_name(overview_table) INTO schema_name, table_name;
|
||||
base_name := _CDB_OverviewBaseTableName(table_name);
|
||||
IF base_name != table_name THEN
|
||||
base_table := Format('%I.%I', schema_name, base_name)::regclass;
|
||||
ELSE
|
||||
base_table := overview_table;
|
||||
END IF;
|
||||
RETURN base_table;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL IMMUTABLE;
|
||||
|
||||
-- Schema and relation names of a table given its reloid
|
||||
-- Scope: private.
|
||||
-- Parameters
|
||||
@@ -215,7 +261,7 @@ AS $$
|
||||
FROM pg_class c JOIN pg_namespace n on n.oid = c.relnamespace WHERE c.oid = reloid::oid;
|
||||
|
||||
ext_query = format(
|
||||
'SELECT ST_EstimatedExtent(''%1$I'', ''%2$I'', ''%3$I'');',
|
||||
'SELECT ST_EstimatedExtent(''%1$s'', ''%2$s'', ''%3$s'');',
|
||||
table_id.schema_name, table_id.table_name, 'the_geom_webmercator'
|
||||
);
|
||||
|
||||
@@ -277,7 +323,11 @@ AS $$
|
||||
WITH RECURSIVE t(x, y, z, e) AS (
|
||||
WITH ext AS (SELECT _cdb_estimated_extent(%6$s) as g),
|
||||
base AS (
|
||||
SELECT (-floor(log(2, (greatest(ST_XMax(ext.g)-ST_XMin(ext.g), ST_YMax(ext.g)-ST_YMin(ext.g))/(%4$s*%5$s))::numeric)))::integer z
|
||||
SELECT
|
||||
least(
|
||||
-floor(log(2, (greatest(ST_XMax(ext.g)-ST_XMin(ext.g), ST_YMax(ext.g)-ST_YMin(ext.g))/(%4$s*%5$s))::numeric)),
|
||||
_CDB_MaxOverviewLevel()+1
|
||||
)::integer z
|
||||
FROM ext
|
||||
),
|
||||
lim AS (
|
||||
@@ -299,10 +349,10 @@ AS $$
|
||||
UNION ALL
|
||||
SELECT x*2 + xx, y*2 + yy, t.z+1, (
|
||||
SELECT count(*) FROM %1$s
|
||||
WHERE the_geom_webmercator && CDB_XYZ_Extent(x*2 + xx, y*2 + yy, t.z+1)
|
||||
WHERE the_geom_webmercator && CDB_XYZ_Extent(t.x*2 + c.xx, t.y*2 + c.yy, t.z+1)
|
||||
)
|
||||
FROM t, base, (VALUES (0, 0), (0, 1), (1, 1), (1, 0)) AS c(xx, yy)
|
||||
WHERE t.e > %2$s AND t.z < (base.z + %3$s)
|
||||
WHERE t.e > %2$s AND t.z < least(base.z + %3$s, _CDB_MaxZoomLevel())
|
||||
)
|
||||
SELECT MAX(e/ST_Area(CDB_XYZ_Extent(x,y,z))) FROM t where e > 0;
|
||||
', reloid::text, min_features, nz, n, c, reloid::oid)
|
||||
@@ -343,7 +393,7 @@ AS $$
|
||||
-- find minimum z so that fd*ta(z) <= lim
|
||||
-- compute a rough 'feature density' value
|
||||
SELECT CDB_XYZ_Resolution(-8) INTO c;
|
||||
RETURN ceil(log(2.0, (c*c*fd/lim)::numeric)/2);
|
||||
RETURN least(_CDB_MaxOverviewLevel()+1, ceil(log(2.0, (c*c*fd/lim)::numeric)/2));
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL STABLE;
|
||||
|
||||
@@ -531,6 +581,54 @@ AS $$
|
||||
);
|
||||
$$ LANGUAGE SQL STABLE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION _cdb_categorical_column(reloid REGCLASS, col_name TEXT)
|
||||
RETURNS BOOLEAN
|
||||
AS $$
|
||||
DECLARE
|
||||
schema_name TEXT;
|
||||
table_name TEXT;
|
||||
available BOOLEAN;
|
||||
categorical BOOLEAN;
|
||||
BEGIN
|
||||
SELECT * FROM _cdb_split_table_name(reloid) INTO schema_name, table_name;
|
||||
SELECT n_distinct IS NOT NULL
|
||||
FROM pg_stats
|
||||
WHERE pg_stats.schemaname = schema_name
|
||||
AND pg_stats.tablename = table_name
|
||||
AND pg_stats.attname = col_name
|
||||
INTO available;
|
||||
IF available IS NULL OR NOT available THEN
|
||||
EXECUTE Format('ANALYZE %s;', reloid);
|
||||
END IF;
|
||||
SELECT n_distinct > 0 AND n_distinct <= 20
|
||||
FROM pg_stats
|
||||
WHERE pg_stats.schemaname = schema_name
|
||||
AND pg_stats.tablename = table_name
|
||||
AND pg_stats.attname = col_name
|
||||
INTO categorical;
|
||||
RETURN categorical;
|
||||
END;
|
||||
$$ LANGUAGE PLPGSQL VOLATILE;
|
||||
|
||||
CREATE OR REPLACE FUNCTION _cdb_mode_of_array(anyarray)
|
||||
RETURNS anyelement AS
|
||||
$$
|
||||
SELECT a
|
||||
FROM unnest($1) a
|
||||
GROUP BY 1
|
||||
ORDER BY COUNT(1) DESC, 1
|
||||
LIMIT 1;
|
||||
$$
|
||||
LANGUAGE SQL IMMUTABLE;
|
||||
|
||||
DROP AGGREGATE IF EXISTS _cdb_mode(anyelement);
|
||||
CREATE AGGREGATE _cdb_mode(anyelement) (
|
||||
SFUNC=array_append,
|
||||
STYPE=anyarray,
|
||||
FINALFUNC=_cdb_mode_of_array,
|
||||
INITCOND='{}'
|
||||
);
|
||||
|
||||
-- SQL Aggregation expression for a datase attribute
|
||||
-- Scope: private.
|
||||
-- Parameters
|
||||
@@ -548,6 +646,7 @@ DECLARE
|
||||
has_counter_column BOOLEAN;
|
||||
feature_count TEXT;
|
||||
total_feature_count TEXT;
|
||||
base_table REGCLASS;
|
||||
BEGIN
|
||||
IF table_alias <> '' THEN
|
||||
qualified_column := Format('%I.%I', table_alias, column_name);
|
||||
@@ -568,20 +667,30 @@ BEGIN
|
||||
total_feature_count := 'count(*)';
|
||||
END IF;
|
||||
|
||||
base_table := _CDB_OverviewBaseTable(reloid);
|
||||
|
||||
CASE column_type
|
||||
WHEN 'double precision', 'real', 'integer', 'bigint', 'numeric' THEN
|
||||
IF column_name = '_feature_count' THEN
|
||||
RETURN 'SUM(_feature_count)';
|
||||
ELSE
|
||||
RETURN Format('SUM(%s*%s)/%s::' || column_type, qualified_column, feature_count, total_feature_count);
|
||||
IF column_type = 'integer' AND _cdb_categorical_column(base_table, column_name) THEN
|
||||
RETURN Format('CDB_Math_Mode(%s)::', qualified_column) || column_type;
|
||||
ELSE
|
||||
RETURN Format('SUM(%s*%s)/%s::' || column_type, qualified_column, feature_count, total_feature_count);
|
||||
END IF;
|
||||
END IF;
|
||||
WHEN 'text', 'character varying', 'character' THEN
|
||||
IF _cdb_unlimited_text_column(reloid, column_name) THEN
|
||||
-- TODO: this should not be applied to columns containing largish text;
|
||||
-- it is intended only to short names/identifiers
|
||||
RETURN 'CASE WHEN count(distinct ' || qualified_column || ') = 1 THEN MIN(' || qualified_column || ') WHEN ' || total_feature_count || ' < 5 THEN string_agg(distinct ' || qualified_column || ','' / '') ELSE ''*'' END::' || column_type;
|
||||
IF _cdb_categorical_column(base_table, column_name) THEN
|
||||
RETURN Format('_cdb_mode(%s)::', qualified_column) || column_type;
|
||||
ELSE
|
||||
RETURN 'CASE count(*) WHEN 1 THEN MIN(' || qualified_column || ') ELSE NULL END::' || column_type;
|
||||
IF _cdb_unlimited_text_column(base_table, column_name) THEN
|
||||
-- TODO: this should not be applied to columns containing largish text;
|
||||
-- it is intended only to short names/identifiers
|
||||
RETURN 'CASE WHEN count(distinct ' || qualified_column || ') = 1 THEN MIN(' || qualified_column || ') WHEN ' || total_feature_count || ' < 5 THEN string_agg(distinct ' || qualified_column || ','' / '') ELSE ''*'' END::' || column_type;
|
||||
ELSE
|
||||
RETURN 'CASE count(*) WHEN 1 THEN MIN(' || qualified_column || ') ELSE NULL END::' || column_type;
|
||||
END IF;
|
||||
END IF;
|
||||
WHEN 'boolean' THEN
|
||||
RETURN 'CASE count(*) WHEN 1 THEN BOOL_AND(' || qualified_column || ') ELSE NULL END::' || column_type;
|
||||
|
||||
@@ -1,30 +1,36 @@
|
||||
CREATE OR REPLACE FUNCTION cartodb.CDB_ZoomFromScale(scaleDenominator numeric) RETURNS int AS $$
|
||||
BEGIN
|
||||
CASE
|
||||
WHEN scaleDenominator > 500000000 THEN RETURN 0;
|
||||
WHEN scaleDenominator <= 500000000 AND scaleDenominator > 200000000 THEN RETURN 1;
|
||||
WHEN scaleDenominator <= 200000000 AND scaleDenominator > 100000000 THEN RETURN 2;
|
||||
WHEN scaleDenominator <= 100000000 AND scaleDenominator > 50000000 THEN RETURN 3;
|
||||
WHEN scaleDenominator <= 50000000 AND scaleDenominator > 25000000 THEN RETURN 4;
|
||||
WHEN scaleDenominator <= 25000000 AND scaleDenominator > 12500000 THEN RETURN 5;
|
||||
WHEN scaleDenominator <= 12500000 AND scaleDenominator > 6500000 THEN RETURN 6;
|
||||
WHEN scaleDenominator <= 6500000 AND scaleDenominator > 3000000 THEN RETURN 7;
|
||||
WHEN scaleDenominator <= 3000000 AND scaleDenominator > 1500000 THEN RETURN 8;
|
||||
WHEN scaleDenominator <= 1500000 AND scaleDenominator > 750000 THEN RETURN 9;
|
||||
WHEN scaleDenominator <= 750000 AND scaleDenominator > 400000 THEN RETURN 10;
|
||||
WHEN scaleDenominator <= 400000 AND scaleDenominator > 200000 THEN RETURN 11;
|
||||
WHEN scaleDenominator <= 200000 AND scaleDenominator > 100000 THEN RETURN 12;
|
||||
WHEN scaleDenominator <= 100000 AND scaleDenominator > 50000 THEN RETURN 13;
|
||||
WHEN scaleDenominator <= 50000 AND scaleDenominator > 25000 THEN RETURN 14;
|
||||
WHEN scaleDenominator <= 25000 AND scaleDenominator > 12500 THEN RETURN 15;
|
||||
WHEN scaleDenominator <= 12500 AND scaleDenominator > 5000 THEN RETURN 16;
|
||||
WHEN scaleDenominator <= 5000 AND scaleDenominator > 2500 THEN RETURN 17;
|
||||
WHEN scaleDenominator <= 2500 AND scaleDenominator > 1500 THEN RETURN 18;
|
||||
WHEN scaleDenominator <= 1500 AND scaleDenominator > 750 THEN RETURN 19;
|
||||
WHEN scaleDenominator <= 750 AND scaleDenominator > 500 THEN RETURN 20;
|
||||
WHEN scaleDenominator <= 500 AND scaleDenominator > 250 THEN RETURN 21;
|
||||
WHEN scaleDenominator <= 250 AND scaleDenominator > 100 THEN RETURN 22;
|
||||
WHEN scaleDenominator <= 100 THEN RETURN 23;
|
||||
END CASE;
|
||||
END
|
||||
$$ LANGUAGE plpgsql IMMUTABLE;
|
||||
-- Maximum supported zoom level
|
||||
CREATE OR REPLACE FUNCTION _CDB_MaxSupportedZoom()
|
||||
RETURNS int
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE
|
||||
AS $$
|
||||
-- The maximum zoom level has to be limited for various reasons,
|
||||
-- e.g. zoom levels greater than 31 would require tile coordinates
|
||||
-- that would not fit in an INTEGER (which is signed, 32 bits long).
|
||||
-- We'll choose 20 as a limit which is safe also when the JavaScript shift
|
||||
-- operator (<<) is used for computing powers of two.
|
||||
SELECT 29;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cartodb.CDB_ZoomFromScale(scaleDenominator numeric)
|
||||
RETURNS int
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE
|
||||
AS $$
|
||||
SELECT
|
||||
CASE
|
||||
WHEN scaleDenominator > 600000000 THEN
|
||||
-- Scale is smaller than zoom level 0
|
||||
NULL
|
||||
WHEN scaleDenominator = 0 THEN
|
||||
-- Actual zoom level would be infinite
|
||||
_CDB_MaxSupportedZoom()
|
||||
ELSE
|
||||
CAST (
|
||||
LEAST(
|
||||
ROUND(LOG(2, 559082264.028/scaleDenominator)),
|
||||
_CDB_MaxSupportedZoom()
|
||||
)
|
||||
AS INTEGER)
|
||||
END;
|
||||
$$;
|
||||
|
||||
Reference in New Issue
Block a user