Merge branch 'add-boundary-bbox-functions' into eliminate-quotes-in-ids

This commit is contained in:
John Krauss 2016-05-03 16:25:55 -04:00
commit fe7035c702
6 changed files with 1566 additions and 45 deletions

View File

@ -202,9 +202,9 @@ Should add the SQL API call here too
# Boundaries
## OBS_GetGeometry(point_geometry, boundary_id)
## OBS_GetBoundary(point_geometry, boundary_id)
The ```OBS_GetGeometry(point_geometry, boundary_id)``` method returns a boundary geometry defined as overlapping the point geometry and from the desired boundary set (e.g. Census Tracts). See the [Boundary ID glossary table below](below). This is a useful method for performing aggregations of points.
The ```OBS_GetBoundary(point_geometry, boundary_id)``` method returns a boundary geometry defined as overlapping the point geometry and from the desired boundary set (e.g. Census Tracts). See the [Boundary ID glossary table below](below). This is a useful method for performing aggregations of points.
#### Arguments
@ -212,6 +212,7 @@ Name | Description
--- | ---
point_geometry | a WGS84 polygon geometry (the_geom)
boundary_id | a boundary identifier from the [Boundary ID glossary table below](below)
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent)
#### Returns
@ -224,23 +225,25 @@ geom | WKB geometry
Overwrite a point geometry with a boundary geometry that contains it in your table
```SQL
UPDATE tablename SET the_geom = OBS_GetGeometry(the_geom, ' "us.census.tiger".block_group')
UPDATE tablename
SET the_geom = OBS_GetBoundary(the_geom, '"us.census.tiger".block_group')
```
<!--
Should add the SQL API call here too
-->
## OBS_GetGeometryId(point_geometry, boundary_id)
## OBS_GetBoundaryId(point_geometry, boundary_id)
The ```OBS_GetGeometryId(point_geometry, boundary_id)``` returns a unique geometry_id for the boundary geometry that contains a given point geometry. See the [Boundary ID glossary table below](below). The method can be combined with ```OBS_GetGeometryById(geometry_id)``` to create a point aggregation workflow.
The ```OBS_GetBoundaryId(point_geometry, boundary_id)``` returns a unique geometry_id for the boundary geometry that contains a given point geometry. See the [Boundary ID glossary table below](below). The method can be combined with ```OBS_GetBoundaryById(geometry_id)``` to create a point aggregation workflow.
#### Arguments
Name |Description
--- | ---
point_geometry | a WGS84 polygon geometry (the_geom)
point_geometry | a WGS84 point geometry (the_geom)
boundary_id | a boundary identifier from the [Boundary ID glossary table below](below)
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent)
#### Returns
@ -253,18 +256,21 @@ geometry_id | a string identifier of a geometry in the Boundaries
Write the geometry_id that contains the point geometry for every row as a new column in your table
```SQL
UPDATE tablename SET new_column_name = OBS_GetGeometryId(the_geom, ' "us.census.tiger".block_group')
UPDATE tablename
SET new_column_name = OBS_GetBoundaryId(the_geom, ' "us.census.tiger".block_group')
```
## OBS_GetGeometryById(geometry_id)
## OBS_GetBoundaryById(geometry_id, boundary_id)
The ```OBS_GetGeometryById(geometry_id)``` returns the boundary geometry for a unique geometry_id. A geometry_id can be found using the ```OBS_GetGeometryId(point_geometry, boundary_id)``` method described above.
The ```OBS_GetBoundaryById(geometry_id, boundary_id)``` returns the boundary geometry for a unique geometry_id. A geometry_id can be found using the ```OBS_GetBoundaryId(point_geometry, boundary_id)``` method described above.
#### Arguments
Name | Description
--- | ---
geometry_id | a string identifier for a Boundary geometry
boundary_id | a boundary identifier from the [Boundary ID glossary table below](below)
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent)
#### Returns
@ -276,10 +282,186 @@ geom | a WGS84 polygon geometry
#### Example
Use a table of geometry_id to select the unique boundaries. Useful with the ```Table from query``` option in CartoDB.
Use a table of geometry_id to select the unique boundaries. Useful with the ```Create Dataset from Query``` option in CartoDB.
```SQL
SELECT OBS_GetGeometryById(geometry_id) the_geom, geometry_id FROM tablename GROUP BY geometry_id
SELECT OBS_GetBoundaryById(geometry_id) As the_geom, geometry_id
FROM tablename
GROUP BY geometry_id
```
## OBS_GetBoundariesByGeometry(geometry, geometry_id)
The ```OBS_GetBoundariesByGeometry(geometry, geometry_id)``` method returns the boundary geometries and their geographical identifiers that intersect (or are contained by) a bounding box polygon.
#### Arguments
Name |Description
--- | ---
geometry | a bounding box
geometry_id | a string identifier for a boundary geometry
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent)
overlap_type (optional) | one of 'intersects' (default), 'contains', or 'within'. See [ST_Intersects](http://postgis.net/docs/manual-2.2/ST_Intersects.html), [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.html), or [ST_Within](http://postgis.net/docs/manual-2.2/ST_Within.html) for more
#### Returns
A table with the following columns:
Column Name | Description
--- | ---
the_geom | a boundary geometry (e.g., US Census tracts)
geom_ref | a string identifier for the geometry (e.g., the geoid of a US Census tract)
#### Example
Get all Census Tracts in Lower Manhattan (geoids beginning with `36061`) without getting Brooklyn or New Jersey
```sql
SELECT *
FROM OBS_GetBoundariesByGeometry(
ST_MakeEnvelope(-74.0251922607,40.6945658517,
-73.9651107788,40.7377626342,
4326),
'"us.census.tiger".census_tract')
WHERE geom_ref like '36061%'
```
#### API Example
Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response:
```text
http://observatory.cartodb.com/api/v2/sql?q=SELECT%20*%20FROM%20OBS_GetBoundariesByGeometry(ST_MakeEnvelope(-105.4287704158,39.4600507935,-104.5089737248,40.0901569675,4326),%27%22us.census.tiger%22.census_tract%27,%272009%27,%27contains%27)
```
## OBS_GetPointsByGeometry(geometry, geometry_id)
The ```OBS_GetPointsByGeometry(geometry, geometry_id)``` method returns point geometries and their geographical identifiers that intersect (or are contained by) a bounding box polygon and lie on the surface of a boundary corresponding to the boundary with same geographical identifiers (e.g., a point that is on a census tract with the same geoid).
#### Arguments
Name |Description
--- | ---
geometry | a bounding box
geometry_id | a string identifier for a boundary geometry
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent)
overlap_type (optional) | one of 'intersects' (default), 'contains', or 'within'. See [ST_Intersects](http://postgis.net/docs/manual-2.2/ST_Intersects.html), [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.html), or [ST_Within](http://postgis.net/docs/manual-2.2/ST_Within.html) for more
#### Returns
A table with the following columns:
Column Name | Description
--- | ---
the_geom | a point geometry on a boundary (e.g., a point that lies on a US Census tract)
geom_ref | a string identifier for the geometry (e.g., the geoid of a US Census tract)
#### Example
Get points in all Census Tracts in Lower Manhattan (geoids beginning with `36061`) without getting Brooklyn or New Jersey
```sql
SELECT *
FROM OBS_GetPointsByGeometry(
ST_MakeEnvelope(-74.0251922607,40.6945658517,
-73.9651107788,40.7377626342,
4326),
'"us.census.tiger".census_tract')
WHERE geom_ref like '36061%'
```
#### API Example
Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response:
```text
http://observatory.cartodb.com/api/v2/sql?q=SELECT%20*%20FROM%20OBS_GetPointsByGeometry(ST_MakeEnvelope(-105.4287704158,39.4600507935,-104.5089737248,40.0901569675,4326),%27%22us.census.tiger%22.census_tract%27,%272009%27,%27contains%27)
```
## OBS_GetBoundariesByPointAndRadius(geometry, radius, boundary_id)
The ```OBS_GetBoundariesByPointAndRadius(geometry, radius, boundary_id)``` method returns boundary geometries and their geographical identifiers that intersect (or are contained by) a circle centered on a point with a radius.
#### Arguments
Name |Description
--- | ---
geometry | a point geometry
radius | a radius (in meters) from the center point
geometry_id | a string identifier for a boundary geometry
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent)
overlap_type (optional) | one of 'intersects' (default), 'contains', or 'within'. See [ST_Intersects](http://postgis.net/docs/manual-2.2/ST_Intersects.html), [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.html), or [ST_Within](http://postgis.net/docs/manual-2.2/ST_Within.html) for more
#### Returns
A table with the following columns:
Column Name | Description
--- | ---
the_geom | a boundary geometry (e.g., a US Census tract)
geom_ref | a string identifier for the geometry (e.g., the geoid of a US Census tract)
#### Example
Get Census tracts which intersect within 10 miles of Downtown, Colorado.
```sql
SELECT *
FROM OBS_GetBoundariesByPointAndRadius(
CDB_LatLng(39.7392, -104.9903), -- Denver, Colorado
10000 * 1.609, -- 10 miles (10km * conversion to miles)
'"us.census.tiger".census_tract')
```
#### API Example
Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response:
```text
http://observatory.cartodb.com/api/v2/sql?q=SELECT%20*%20FROM%20OBS_GetBoundariesByPointAndRadius(CDB_LatLng(39.7392,-104.9903),10000*1609),%27%22us.census.tiger%22.census_tract%27,%272009%27,%27contains%27)
```
## OBS_GetPointsByPointAndRadius(geometry, radius, boundary_id)
The ```OBS_GetPointsByPointAndRadius(geometry, radius, boundary_id)``` method returns point geometries on boundaries (e.g., a point that lies on a Census tract) and their geographical identifiers that intersect (or are contained by) a circle centered on a point with a radius.
#### Arguments
Name |Description
--- | ---
geometry | a point geometry
radius | radius (in meters)
geometry_id | a string identifier for a boundary geometry
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent)
overlap_type (optional) | one of 'intersects' (default), 'contains', or 'within'. See [ST_Intersects](http://postgis.net/docs/manual-2.2/ST_Intersects.html), [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.html), or [ST_Within](http://postgis.net/docs/manual-2.2/ST_Within.html) for more
#### Returns
A table with the following columns:
Column Name | Description
--- | ---
the_geom | a point geometry (e.g., a point on a US Census tract)
geom_ref | a string identifier for the geometry (e.g., the geoid of a US Census tract)
#### Example
Get Census tracts which intersect within 10 miles of Downtown, Colorado.
```sql
SELECT *
FROM OBS_GetPointsByPointAndRadius(
CDB_LatLng(39.7392, -104.9903), -- Denver, Colorado
10000 * 1.609, -- 10 miles (10km * conversion to miles)
'"us.census.tiger".census_tract')
```
#### API Example
Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response:
```text
http://observatory.cartodb.com/api/v2/sql?q=SELECT%20*%20FROM%20OBS_GetPointsByPointAndRadius(CDB_LatLng(39.7392,-104.9903),10000*1609),%27%22us.census.tiger%22.census_tract%27,%272009%27,%27contains%27)
```
# Discovery
@ -299,7 +481,7 @@ boundary_id | a string identifier for a Boundary geometry (optional)
Key | Description
--- | ---
measure_id | the unique id of the measue for use with the ```OBS_GetMeasure``` method
measure_id | the unique id of the measure for use with the ```OBS_GetMeasure``` method
name | the human readable name of the measure
description | a brief description of the measure
aggregate_type | **sum** are raw count values, **median** are statistical medians, **average** are statistical averages, **undefined** other (e.g. an index value)

View File

@ -196,29 +196,8 @@ DECLARE
geom_colname text;
BEGIN
EXECUTE
format(
$string$
SELECT geoid_ct.colname As geoid_colname,
tablename,
geom_ct.colname As geom_colname
FROM observatory.obs_column_table As geoid_ct,
observatory.obs_table As geom_t,
observatory.obs_column_table As geom_ct,
observatory.obs_column As geom_c
WHERE geoid_ct.column_id
IN (
SELECT source_id
FROM observatory.obs_column_to_column
WHERE reltype = 'geom_ref'
AND target_id = '%s'
)
AND geoid_ct.table_id = geom_t.id and
geom_t.id = geom_ct.table_id and
geom_ct.column_id = geom_c.id and
geom_c.type ILIKE 'geometry'
$string$, boundary_id
) INTO geoid_colname, target_table, geom_colname;
SELECT * INTO geoid_colname, target_table, geom_colname
FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id);
RAISE NOTICE '%', target_table;
@ -242,3 +221,332 @@ BEGIN
END;
$$ LANGUAGE plpgsql;
-- _OBS_GetBoundariesByGeometry
-- internal function for retrieving geometries based on an input geometry
-- see OBS_GetBoundariesByGeometry or OBS_GetBoundariesByPointAndRadius for
-- more information
CREATE OR REPLACE FUNCTION cdb_observatory._OBS_GetBoundariesByGeometry(
geom geometry(Geometry, 4326),
boundary_id text,
time_span text DEFAULT NULL,
overlap_type text DEFAULT 'intersects')
RETURNS TABLE(the_geom geometry, geom_refs text)
AS $$
DECLARE
boundary geometry(Geometry, 4326);
geom_colname text;
geoid_colname text;
target_table text;
BEGIN
-- check inputs
IF lower(overlap_type) NOT IN ('contains', 'intersects', 'within')
THEN
-- recognized overlap type (map to ST_Contains, ST_Intersects, and ST_Within)
RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose intersects, within, or contains)', overlap_type;
ELSIF ST_GeometryType(geom) NOT IN ('ST_Polygon', 'ST_MultiPolygon')
THEN
RAISE EXCEPTION 'Invalid geometry type (%), expecting ''ST_MultiPolygon'' or ''ST_Polygon''', ST_GeometryType(geom);
END IF;
-- TODO: add timespan in search
-- TODO: add overlap info in search
SELECT * INTO geoid_colname, target_table, geom_colname
FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id);
-- if no tables are found, raise notice and return null
IF target_table IS NULL
THEN
RAISE NOTICE 'No boundaries found for bounding box ''%'' in ''%''', ST_AsText(geom), boundary_id;
RETURN QUERY SELECT NULL::geometry, NULL::text;
END IF;
RAISE NOTICE 'target_table: %', target_table;
-- return first boundary in intersections
RETURN QUERY
EXECUTE format(
'SELECT t.%s, t.%s
FROM observatory.%s As t
WHERE ST_%s($1, t.the_geom)
', geom_colname, geoid_colname, target_table, overlap_type)
USING geom;
END;
$$ LANGUAGE plpgsql;
-- OBS_GetBoundariesByGeometry
--
-- Given a bounding box (or a polygon), and it's geometry level (see
-- OBS_ListGeomColumns() for all available boundary ids), give back the
-- boundaries that are contained within the bounding box polygon and the
-- associated geometry ids
-- Inputs:
-- geom geometry: bounding box (or polygon) of the region of interest
-- boundary_id text: source id of boundaries (e.g., us.census.tiger.county)
-- see function OBS_ListGeomColumns for all avaiable
-- boundary ids
-- time_span text: time span that the geometries were collected (optional)
--
-- Output:
-- table with the following columns
-- boundary geometry: geometry boundary that is contained within the input
-- bounding box at the requested geometry level
-- with boundary_id, and time_span
-- geom_refs text: geometry identifiers (e.g., geoid for the US Census)
--
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundariesByGeometry(
geom geometry(Geometry, 4326),
boundary_id text,
time_span text DEFAULT NULL,
overlap_type text DEFAULT 'intersects')
RETURNS TABLE(the_geom geometry, geom_refs text)
AS $$
BEGIN
RETURN QUERY SELECT *
FROM cdb_observatory._OBS_GetBoundariesByGeometry(
geom,
boundary_id,
time_span,
overlap_type
);
END;
$$ LANGUAGE plpgsql;
-- OBS_GetBoundariesByPointAndRadius
--
-- Given a point and radius, and it's geometry level (see
-- OBS_ListGeomColumns() for all available boundary ids), give back the
-- boundaries that are contained within the point buffered by radius meters and
-- the associated geometry ids
-- Inputs:
-- geom geometry: point geometry centered on area of interest
-- radius numeric: radius (in meters) of a circle centered on geom for
-- selecting polygons
-- boundary_id text: source id of boundaries (e.g., us.census.tiger.county)
-- see function OBS_ListGeomColumns for all avaiable
-- boundary ids
-- time_span text: time span that the geometries were collected (optional)
--
-- Output:
-- table with the following columns
-- boundary geometry: geometry boundary that is contained within the input
-- bounding box at the requested geometry level
-- with boundary_id, and time_span
-- geom_refs text: geometry identifiers (e.g., geoid for the US Census)
--
-- TODO: move to ST_DWithin instead of buffer + intersects?
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundariesByPointAndRadius(
geom geometry(Geometry, 4326), -- point
radius numeric, -- radius in meters
boundary_id text,
time_span text DEFAULT NULL,
overlap_type text DEFAULT 'intersects')
RETURNS TABLE(the_geom geometry, geom_refs text)
AS $$
DECLARE
circle_boundary geometry(Geometry, 4326);
BEGIN
IF ST_GeometryType(geom) != 'ST_Point'
THEN
RAISE EXCEPTION 'Input geometry ''%'' is not a point', ST_AsText(geom);
ELSE
circle_boundary := ST_Buffer(geom::geography, radius)::geometry;
END IF;
RETURN QUERY SELECT *
FROM cdb_observatory._OBS_GetBoundariesByGeometry(
circle_boundary,
boundary_id,
time_span);
END;
$$ LANGUAGE plpgsql;
-- _OBS_GetPointsByGeometry
CREATE OR REPLACE FUNCTION cdb_observatory._OBS_GetPointsByGeometry(
geom geometry(Geometry, 4326),
boundary_id text,
time_span text DEFAULT NULL,
overlap_type text DEFAULT 'intersects')
RETURNS TABLE(the_geom geometry, geom_refs text)
AS $$
DECLARE
boundary geometry(Geometry, 4326);
geom_colname text;
geoid_colname text;
target_table text;
BEGIN
IF lower(overlap_type) NOT IN ('contains', 'within', 'intersects')
THEN
RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose intersects, within, or contains)', overlap_type;
ELSIF ST_GeometryType(geom) NOT IN ('ST_Polygon', 'ST_MultiPolygon')
THEN
RAISE EXCEPTION 'Invalid geometry type (%), expecting ''ST_MultiPolygon'' or ''ST_Polygon''', ST_GeometryType(geom);
END IF;
SELECT * INTO geoid_colname, target_table, geom_colname
FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id);
-- if no tables are found, raise notice and return null
IF target_table IS NULL
THEN
RAISE NOTICE 'No boundaries found for bounding box ''%'' in ''%''', ST_AsText(geom), boundary_id;
RETURN QUERY SELECT NULL::geometry, NULL::text;
END IF;
RAISE NOTICE 'target_table: %', target_table;
-- return first boundary in intersections
RETURN QUERY
EXECUTE format(
'SELECT ST_PointOnSurface(t.%s) As %s, t.%s
FROM observatory.%s As t
WHERE ST_%s($1, t.the_geom)
', geom_colname, geom_colname, geoid_colname, target_table, overlap_type)
USING geom;
END;
$$ LANGUAGE plpgsql;
-- OBS_GetPointsByGeometry
--
-- Given a polygon, and it's geometry level (see
-- OBS_ListGeomColumns() for all available boundary ids), give back a point
-- which lies in a boundary from the requested geometry level that is contained
-- within the bounding box polygon and the associated geometry ids
--
-- Inputs:
-- geom geometry: bounding box (or polygon) of the region of interest
-- boundary_id text: source id of boundaries (e.g., us.census.tiger.county)
-- see function OBS_ListGeomColumns for all avaiable
-- boundary ids
-- time_span text: time span that the geometries were collected (optional)
--
-- Output:
-- table with the following columns
-- boundary geometry: point that lies on a boundary that is contained within
-- the input bounding box at the requested geometry
-- level with boundary_id, and time_span
-- geom_refs text: geometry identifiers (e.g., geoid for the US Census)
--
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByGeometry(
geom geometry(Geometry, 4326),
boundary_id text,
time_span text DEFAULT NULL,
overlap_type text DEFAULT 'intersects')
RETURNS TABLE(the_geom geometry, geom_refs text)
AS $$
BEGIN
RETURN QUERY SELECT *
FROM cdb_observatory._OBS_GetPointsByGeometry(
geom,
boundary_id,
time_span,
overlap_type);
END;
$$ LANGUAGE plpgsql;
-- OBS_GetBoundariesByPointAndRadius
--
-- Given a point and radius, and it's geometry level (see
-- OBS_ListGeomColumns() for all available boundary ids), give back the
-- boundaries that are contained within the point buffered by radius meters and
-- the associated geometry ids
-- Inputs:
-- geom geometry: point geometry centered on area of interest
-- radius numeric: radius (in meters) of a circle centered on geom for
-- selecting polygons
-- boundary_id text: source id of boundaries (e.g., us.census.tiger.county)
-- see function OBS_ListGeomColumns for all avaiable
-- boundary ids
-- time_span text: time span that the geometries were collected (optional)
--
-- Output:
-- table with the following columns
-- boundary geometry: geometry boundary that is contained within the input
-- bounding box at the requested geometry level
-- with boundary_id, and time_span
-- geom_refs text: geometry identifiers (e.g., geoid for the US Census)
--
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByPointAndRadius(
geom geometry(Geometry, 4326), -- point
radius numeric, -- radius in meters
boundary_id text,
time_span text DEFAULT NULL,
overlap_type text DEFAULT 'intersects')
RETURNS TABLE(the_geom geometry, geom_refs text)
AS $$
DECLARE
circle_boundary geometry(Geometry, 4326);
BEGIN
IF ST_GeometryType(geom) != 'ST_Point'
THEN
RAISE EXCEPTION 'Input geometry ''%'' is not a point', ST_AsText(geom);
ELSE
circle_boundary := ST_Buffer(geom::geography, radius)::geometry;
END IF;
RETURN QUERY SELECT *
FROM cdb_observatory._OBS_GetPointsByGeometry(
ST_Buffer(geom::geography, radius)::geometry,
boundary_id,
time_span,
overlap_type);
END;
$$ LANGUAGE plpgsql;
-- _OBS_GetGeometryMetadata()
-- TODO: add timespan in search
-- TODO: add choice of clipped versus not clipped
CREATE OR REPLACE FUNCTION cdb_observatory._OBS_GetGeometryMetadata(boundary_id text)
RETURNS table(geoid_colname text, target_table text, geom_colname text)
AS $$
BEGIN
RETURN QUERY
EXECUTE
format($string$
SELECT geoid_ct.colname As geoid_colname,
tablename,
geom_ct.colname As geom_colname
FROM observatory.obs_column_table As geoid_ct,
observatory.obs_table As geom_t,
observatory.obs_column_table As geom_ct,
observatory.obs_column As geom_c
WHERE geoid_ct.column_id
IN (
SELECT source_id
FROM observatory.obs_column_to_column
WHERE reltype = 'geom_ref'
AND target_id = '%s'
)
AND geoid_ct.table_id = geom_t.id AND
geom_t.id = geom_ct.table_id AND
geom_ct.column_id = geom_c.id AND
geom_c.type ILIKE 'geometry'
LIMIT 1
$string$, boundary_id);
-- AND geom_t.timespan = '%s' <-- put in requested year
-- TODO: filter by clipped vs. not so appropriate tablename are unique
-- so the limit 1 can be removed
END;
$$ LANGUAGE plpgsql;

View File

@ -69,6 +69,51 @@ t
obs_getboundarybyid_boundary_id_mismatch_geom_id
t
(1 row)
_obs_getboundariesbygeometry_tracts_around_cartodb
t
(1 row)
_obs_getboundariesbygeometry_tracts_around_null_island
t
(1 row)
obs_getboundariesbygeometry_tracts_around_cartodb
t
(1 row)
obs_getboundariesbygeometry_tracts_around_null_island
t
(1 row)
obs_getboundariesbypointandradius_around_cartodb
t
(1 row)
obs_getboundariesbypointandradius_around_null_island
t
(1 row)
_obs_getpointsbygeometry_around_cartodb
t
(1 row)
_obs_getpointsbygeometry_around_null_island
t
(1 row)
obs_getpointsbygeometry_around_cartodb
t
(1 row)
obs_getpointsbygeometry_around_cartodb_2013
t
(1 row)
obs_getpointsbygeometry_around_null_island
t
(1 row)
obs_getpointsbypointandradius_around_cartodb
t
(1 row)
obs_getpointsbypointandradius_around_cartodb_2013
t
(1 row)
obs_getpointsbypointandradius_around_null_island
t
(1 row)
geoid_name_matches|table_name_matches|geom_name_matches
t|t|t
(1 row)
Dropping obs_table.sql fixture table...
Done.
Dropping obs_column.sql fixture table...

File diff suppressed because one or more lines are too long

View File

@ -87,7 +87,7 @@ SELECT
cdb_observatory._TestPoint(),
'obs_a92e1111ad3177676471d66bb8036e6d057f271b'::text, -- see example in obs_geomtable
(Array['{"colname":"total_pop","tablename":"obs_ab038198aaab3f3cb055758638ee4de28ad70146","aggregate":"sum","name":"Total Population","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'::json])
))[1]::text = '{"value":4809.33511352425,"name":"Total Population","tablename":"obs_ab038198aaab3f3cb055758638ee4de28ad70146","aggregate":"sum","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'
))[1]::text = '{"value":4809.07989821893,"name":"Total Population","tablename":"obs_ab038198aaab3f3cb055758638ee4de28ad70146","aggregate":"sum","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'
as OBS_GetPoints_for_test_point;
-- what happens at null island
@ -109,7 +109,7 @@ SELECT
cdb_observatory._TestArea(),
'obs_a92e1111ad3177676471d66bb8036e6d057f271b'::text, -- see example in obs_geomtable
Array['{"colname":"total_pop","tablename":"obs_ab038198aaab3f3cb055758638ee4de28ad70146","aggregate":"sum","name":"Total Population","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'::json]
))[1]::text = '{"value":1570.72353789469,"name":"Total Population","tablename":"obs_ab038198aaab3f3cb055758638ee4de28ad70146","aggregate":"sum","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'
))[1]::text = '{"value":1570.78845496678,"name":"Total Population","tablename":"obs_ab038198aaab3f3cb055758638ee4de28ad70146","aggregate":"sum","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'
as OBS_GetPolygons_for_test_point;
-- see what happens around null island

View File

@ -112,4 +112,219 @@ SELECT cdb_observatory.OBS_GetBoundaryById(
'us.census.tiger.census_tract'
) IS NULL As OBS_GetBoundaryById_boundary_id_mismatch_geom_id;
-- _OBS_GetBoundariesByGeometry
-- check that all census tracts intersecting with the geometry are returned
-- order them to ensure that the same values are returned
SELECT
array_agg(geom_refs) = Array['36047025700','36047028501','36047038900','36047039100','36047042300','36047042500','36047042700','36047044900','36047045300','36047048500','36047048900','36047049100','36047049300','36047050500','36047050700'] As _OBS_GetBoundariesByGeometry_tracts_around_cartodb
FROM (
SELECT *
FROM cdb_observatory._OBS_GetBoundariesByGeometry(
-- near CartoDB's office
ST_MakeEnvelope(-73.9452409744,40.6988851644,-73.9280319214,40.7101254524,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- Null Island area
SELECT
array_length(array_agg(geom_refs), 1) IS NULL As _OBS_GetBoundariesByGeometry_tracts_around_null_island
FROM (
SELECT *
FROM cdb_observatory._OBS_GetBoundariesByGeometry(
-- around null island
ST_MakeEnvelope(-0.1400756836,-0.2114863362,0.1455688477,0.2059932086,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- OBS_GetBoundariesByGeometry
-- check that all census tracts intersecting with the geometry are returned
-- order them to ensure that the same values are returned
SELECT
array_agg(geom_refs) = Array['36047025700','36047028501','36047038900','36047039100','36047042300','36047042500','36047042700','36047044900','36047045300','36047048500','36047048900','36047049100','36047049300','36047050500','36047050700'] As OBS_GetBoundariesByGeometry_tracts_around_cartodb
FROM (
SELECT *
FROM cdb_observatory.OBS_GetBoundariesByGeometry(
-- near CartoDB's office
ST_MakeEnvelope(-73.9452409744,40.6988851644,-73.9280319214,40.7101254524,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- Null Island area
SELECT
array_length(array_agg(geom_refs), 1) IS NULL As OBS_GetBoundariesByGeometry_tracts_around_null_island
FROM (
SELECT *
FROM cdb_observatory.OBS_GetBoundariesByGeometry(
-- around null island
ST_MakeEnvelope(-0.1400756836,-0.2114863362,0.1455688477,0.2059932086,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- OBS_GetBoundariesByPointAndRadius
-- check that all census tracts intersecting with the geometry are returned
-- order them to ensure that the same values are returned
SELECT
array_agg(geom_refs) = Array['36047038900','36047039100','36047042500','36047042700','36047045300','36047048500','36047048900','36047049100','36047049300'] As OBS_GetBoundariesByPointAndRadius_around_cartodb
FROM (
SELECT *
FROM cdb_observatory.OBS_GetBoundariesByPointAndRadius(
-- 500 meter circle centered on CartoDB's office
cdb_observatory._testPoint(),
500,
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- Null Island area
SELECT
array_length(array_agg(geom_refs), 1) IS NULL As OBS_GetBoundariesByPointAndRadius_around_null_island
FROM (
SELECT *
FROM cdb_observatory.OBS_GetBoundariesByPointAndRadius(
-- around null island
ST_SetSRID(ST_Point(0, 0), 4326),
500,
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- _OBS_GetPointsByGeometry
-- check that all census tracts intersecting with the geometry are returned
-- order them to ensure that the same values are returned
SELECT
array_agg(geom_refs) = Array['36047025700','36047028501','36047038900','36047039100','36047042300','36047042500','36047042700','36047044900','36047045300','36047048500','36047048900','36047049100','36047049300','36047050500','36047050700'] As _OBS_GetPointsByGeometry_around_cartodb
FROM (
SELECT *
FROM cdb_observatory._OBS_GetPointsByGeometry(
-- around CartoDB's Brooklyn office
ST_MakeEnvelope(-73.9452409744,40.6988851644,
-73.9280319214,40.7101254524,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- Null Island area
SELECT
array_length(array_agg(geom_refs), 1) IS NULL As _OBS_GetPointsByGeometry_around_null_island
FROM (
SELECT *
FROM cdb_observatory._OBS_GetPointsByGeometry(
-- around null island
ST_MakeEnvelope(-0.1400756836,-0.2114863362,
0.1455688477, 0.2059932086,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- OBS_GetPointsByGeometry
-- check that all census tracts intersecting with the geometry are returned
-- order them to ensure that the same values are returned
SELECT
array_agg(geom_refs) = Array['36047025700','36047028501','36047038900','36047039100','36047042300','36047042500','36047042700','36047044900','36047045300','36047048500','36047048900','36047049100','36047049300','36047050500','36047050700'] As OBS_GetPointsByGeometry_around_cartodb
FROM (
SELECT *
FROM cdb_observatory.OBS_GetBoundariesByGeometry(
-- around CartoDB's Brooklyn office
ST_MakeEnvelope(-73.9452409744,40.6988851644,
-73.9280319214,40.7101254524,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
SELECT
array_agg(geom_refs) = Array['36047025700','36047028501','36047038900','36047039100','36047042300','36047042500','36047042700','36047044900','36047045300','36047048500','36047048900','36047049100','36047049300','36047050500','36047050700'] As OBS_GetPointsByGeometry_around_cartodb_2013
FROM (
SELECT *
FROM cdb_observatory.OBS_GetBoundariesByGeometry(
-- around CartoDB's Brooklyn office
ST_MakeEnvelope(-73.9452409744,40.6988851644,
-73.9280319214,40.7101254524,
4326),
'"us.census.tiger".census_tract',
'2013')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- Null Island area
SELECT
array_length(array_agg(geom_refs), 1) IS NULL As OBS_GetPointsByGeometry_around_null_island
FROM (
SELECT *
FROM cdb_observatory.OBS_GetBoundariesByGeometry(
-- around null island
ST_MakeEnvelope(-0.1400756836,-0.2114863362,
0.1455688477, 0.2059932086,
4326),
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- OBS_GetPointsByPointAndRadius
-- check that all census tracts intersecting with the geometry are returned
-- order them to ensure that the same values are returned
SELECT
array_agg(geom_refs) = Array['36047038900','36047039100','36047042500','36047042700','36047045300','36047048500','36047048900','36047049100','36047049300'] As OBS_GetPointsByPointAndRadius_around_cartodb
FROM (
SELECT *
FROM cdb_observatory.OBS_GetPointsByPointAndRadius(
-- around CartoDB's Brooklyn office
cdb_observatory._testpoint(),
500,
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
SELECT
array_agg(geom_refs) = Array['36047038900','36047039100','36047042500','36047042700','36047045300','36047048500','36047048900','36047049100','36047049300'] As OBS_GetPointsByPointAndRadius_around_cartodb_2013
FROM (
SELECT *
FROM cdb_observatory.OBS_GetPointsByPointAndRadius(
-- around CartoDB's Brooklyn office
cdb_observatory._testpoint(),
500,
'"us.census.tiger".census_tract',
'2013')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- Null Island area
SELECT
array_length(array_agg(geom_refs), 1) IS NULL As OBS_GetPointsByPointAndRadius_around_null_island
FROM (
SELECT *
FROM cdb_observatory.OBS_GetPointsByPointAndRadius(
-- around null island
ST_SetSRID(ST_Point(0, 0), 4326),
500,
'"us.census.tiger".census_tract')
ORDER BY geom_refs ASC
) As m(the_geom, geom_refs);
-- _OBS_GetGeometryMetadata
SELECT
geoid_colname = 'geoid' As geoid_name_matches,
target_table = 'obs_a92e1111ad3177676471d66bb8036e6d057f271b' As table_name_matches,
geom_colname = 'the_geom' As geom_name_matches
FROM cdb_observatory._OBS_GetGeometryMetadata('"us.census.tiger".census_tract')
As m(geoid_colname, target_table, geom_colname);
\i test/sql/drop_fixtures.sql