extracting getboundariesbybbox to interal, more general function

This commit is contained in:
Andy Eschbacher 2016-05-02 12:12:49 -04:00
parent c5a49ade60
commit 2200b2e437
2 changed files with 103 additions and 57 deletions

View File

@ -290,9 +290,9 @@ FROM tablename
GROUP BY geometry_id GROUP BY geometry_id
``` ```
## OBS_GetBoundariesByBBox(geometry, geometry_id) ## OBS_GetBoundariesByGeometry(geometry, geometry_id)
The ```OBS_GetBoundariesByBBox(geometry, geometry_id)``` method returns the boundary geometries and their geographical identifiers that intersect (or are contained by) a bounding box polygon. 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 #### Arguments
@ -301,7 +301,7 @@ Name |Description
geometry | a bounding box geometry | a bounding box
geometry_id | a string identifier for a boundary geometry geometry_id | a string identifier for a boundary geometry
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent) 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) or [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.html) for more 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 #### Returns
@ -318,7 +318,7 @@ Get all Census Tracts in Lower Manhattan (geoids beginning with `36061`) without
```sql ```sql
SELECT * SELECT *
FROM OBS_GetBoundariesByBBox( FROM OBS_GetBoundariesByGeometry(
ST_MakeEnvelope(-74.0251922607,40.6945658517, ST_MakeEnvelope(-74.0251922607,40.6945658517,
-73.9651107788,40.7377626342, -73.9651107788,40.7377626342,
4326), 4326),
@ -331,12 +331,12 @@ WHERE geom_ref like '36061%'
Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response: Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response:
```text ```text
http://observatory.cartodb.com/api/v2/sql?q=SELECT%20*%20FROM%20OBS_GetBoundariesByBBox(ST_MakeEnvelope(-105.4287704158,39.4600507935,-104.5089737248,40.0901569675,4326),%27%22us.census.tiger%22.census_tract%27,%272009%27,%27contains%27) 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_GetPointsByBBox(geometry, geometry_id) ## OBS_GetPointsByGeometry(geometry, geometry_id)
The ```OBS_GetPointsByBBox(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). 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 #### Arguments
@ -345,7 +345,7 @@ Name |Description
geometry | a bounding box geometry | a bounding box
geometry_id | a string identifier for a boundary geometry geometry_id | a string identifier for a boundary geometry
timespan (optional) | year(s) to request from (`NULL` (default) gives most recent) 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) or [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.html) for more 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 #### Returns
@ -362,7 +362,7 @@ Get points in all Census Tracts in Lower Manhattan (geoids beginning with `36061
```sql ```sql
SELECT * SELECT *
FROM OBS_GetPointsByBBox( FROM OBS_GetPointsByGeometry(
ST_MakeEnvelope(-74.0251922607,40.6945658517, ST_MakeEnvelope(-74.0251922607,40.6945658517,
-73.9651107788,40.7377626342, -73.9651107788,40.7377626342,
4326), 4326),
@ -375,7 +375,7 @@ WHERE geom_ref like '36061%'
Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response: Retrieve all Census tracts contained in a bounding box around Denver, CO as a JSON response:
```text ```text
http://observatory.cartodb.com/api/v2/sql?q=SELECT%20*%20FROM%20OBS_GetPointsByBBox(ST_MakeEnvelope(-105.4287704158,39.4600507935,-104.5089737248,40.0901569675,4326),%27%22us.census.tiger%22.census_tract%27,%272009%27,%27contains%27) 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) ## OBS_GetBoundariesByPointAndRadius(geometry, radius, boundary_id)

View File

@ -222,30 +222,12 @@ BEGIN
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- _OBS_GetBoundariesByGeometry
-- internal function for retrieving geometries based on an input geometry
-- see OBS_GetBoundariesByGeometry or OBS_GetBoundariesByPointAndRadius for
-- more information
-- OBS_GetBoundariesByBBox CREATE OR REPLACE FUNCTION cdb_observatory._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_GetBoundariesByBBox(
geom geometry(Geometry, 4326), geom geometry(Geometry, 4326),
boundary_id text, boundary_id text,
time_span text DEFAULT NULL, time_span text DEFAULT NULL,
@ -298,6 +280,48 @@ BEGIN
END; END;
$$ LANGUAGE plpgsql; $$ 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 -- OBS_GetBoundariesByPointAndRadius
-- --
-- Given a point and radius, and it's geometry level (see -- Given a point and radius, and it's geometry level (see
@ -342,36 +366,17 @@ BEGIN
END IF; END IF;
RETURN QUERY SELECT * RETURN QUERY SELECT *
FROM cdb_observatory.OBS_GetBoundariesByBBox( FROM cdb_observatory._OBS_GetBoundariesByGeometry(
circle_boundary, circle_boundary,
boundary_id, boundary_id,
time_span); time_span);
END; END;
$$ LANGUAGE plpgsql; $$ LANGUAGE plpgsql;
-- OBS_GetPointsByBBox -- _OBS_GetPointsByGeometry
--
-- Given a bounding box (or 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_GetPointsByBBox(
CREATE OR REPLACE FUNCTION cdb_observatory._OBS_GetPointsByGeometry(
geom geometry(Geometry, 4326), geom geometry(Geometry, 4326),
boundary_id text, boundary_id text,
time_span text DEFAULT NULL, time_span text DEFAULT NULL,
@ -417,6 +422,47 @@ BEGIN
END; END;
$$ LANGUAGE plpgsql; $$ 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 -- OBS_GetBoundariesByPointAndRadius
-- --
-- Given a point and radius, and it's geometry level (see -- Given a point and radius, and it's geometry level (see
@ -459,7 +505,7 @@ BEGIN
END IF; END IF;
RETURN QUERY SELECT * RETURN QUERY SELECT *
FROM cdb_observatory.OBS_GetPointsByBBox( FROM cdb_observatory._OBS_GetPointsByGeometry(
ST_Buffer(geom::geography, radius)::geometry, ST_Buffer(geom::geography, radius)::geometry,
boundary_id, boundary_id,
time_span, time_span,