From 1a19e338770458a6b52a639a37d706d8915b4809 Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Thu, 28 Apr 2016 11:14:15 -0700 Subject: [PATCH 01/15] adding boundaries by bbox functions --- src/pg/sql/44_observatory_geometries.sql | 175 +++++++++++++++++++++++ 1 file changed, 175 insertions(+) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index 59cec2c..48af9be 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -242,3 +242,178 @@ BEGIN END; $$ LANGUAGE plpgsql; + + +-- OBS_GetBoundariesByBBox +-- +-- 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), + boundary_id text, + time_span text DEFAULT NULL) +RETURNS TABLE(boundary geometry, geom_refs text) +AS $$ +DECLARE + boundary geometry(Geometry, 4326); + geom_colname text; + geoid_colname text; + target_table text; +BEGIN + +-- TODO: add timespan in search +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; + + -- if not a point, raise error + IF 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; + + -- 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_Contains($1, t.the_geom) + ', geom_colname, geoid_colname, target_table) + USING geom; + +END; +$$ LANGUAGE plpgsql; + +-- OBS_GetPointsByBBox +-- +-- 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( + geom geometry(Geometry, 4326), + boundary_id text, + time_span text DEFAULT NULL) +RETURNS TABLE(boundary geometry, geom_refs text) +AS $$ +DECLARE + boundary geometry(Geometry, 4326); + geom_colname text; + geoid_colname text; + target_table text; +BEGIN + +-- TODO: add timespan in search +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; + + -- if not a point, raise error + IF 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; + + -- 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_Contains($1, t.the_geom) + ', geom_colname, geom_colname, geoid_colname, target_table) + USING geom; + +END; +$$ LANGUAGE plpgsql; From 0ba66c8f31042bc66a502efbaf8b99e71984e90d Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Thu, 28 Apr 2016 12:05:36 -0700 Subject: [PATCH 02/15] adding point and radius functions --- src/pg/sql/44_observatory_geometries.sql | 90 ++++++++++++++++++++++++ 1 file changed, 90 insertions(+) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index 48af9be..818807b 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -331,6 +331,51 @@ format( 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_GetBoundariesByPointAndRadius( + geom geometry(Geometry, 4326), -- point + radius numeric, -- radius in meters + boundary_id text, + time_span text DEFAULT NULL) +RETURNS TABLE(boundary geometry, geom_refs text) +AS $$ +DECLARE + circle_boundary geometry(Geometry, 4326); +BEGIN + + circle_boundary := ST_Buffer(geom::geography, radius)::geometry; + + RETURN QUERY SELECT * + FROM cdb_observatory.OBS_GetBoundariesByBBox( + circle_boundary, + boundary_id, + time_span); +END; +$$ LANGUAGE plpgsql; + -- OBS_GetPointsByBBox -- -- Given a bounding box (or a polygon), and it's geometry level (see @@ -417,3 +462,48 @@ format( 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) +RETURNS TABLE(boundary geometry, geom_refs text) +AS $$ +DECLARE + circle_boundary geometry(Geometry, 4326); +BEGIN + + circle_boundary := ST_Buffer(geom::geography, radius)::geometry; + + RETURN QUERY SELECT * + FROM cdb_observatory.OBS_GetPointsByBBox( + circle_boundary, + boundary_id, + time_span); +END; +$$ LANGUAGE plpgsql; From ab93ff4ec0ce69f746848ece355b59491c8138c9 Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Thu, 28 Apr 2016 16:25:10 -0700 Subject: [PATCH 03/15] adding _obs_getgeometrymetadata function --- src/pg/sql/44_observatory_geometries.sql | 154 ++++++++++------------- 1 file changed, 68 insertions(+), 86 deletions(-) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index 818807b..af7354e 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -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; @@ -279,36 +258,23 @@ DECLARE target_table text; BEGIN --- TODO: add timespan in search -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; - - -- if not a point, raise error - IF ST_GeometryType(geom) NOT IN ('ST_Polygon', 'ST_MultiPolygon') - THEN +-- 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 contains, within, intersects)', 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; +END IF; + +-- TODO: add timespan in search +-- TODO: add overlap info in search +-- TODO: turn this into a function _OBS_GetGeometryMetadata(geo_ref_name, tablename, and geom_colname) +-- SELECT geo_ref_name, tablename, geom_colname INTO a, b, c +-- FROM _OBS_GetGeometryMetadata +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 @@ -411,36 +377,19 @@ DECLARE target_table text; BEGIN --- TODO: add timespan in search -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; - - -- if not a point, raise error - IF ST_GeometryType(geom) NOT IN ('ST_Polygon', 'ST_MultiPolygon') - THEN +IF lower(overlap_type) NOT IN ('contains', 'within', 'intersects') +THEN + RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose contains, within, intersects)', 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; +END IF; + +SELECT * INTO geoid_colname, target_table, geom_colname +FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id); + +RAISE NOTICE 'geoid_colname: %, target_table: %, geom_colname: %', + geoid_colname, target_table, geom_colname; -- if no tables are found, raise notice and return null IF target_table IS NULL @@ -494,16 +443,49 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByPointAndRadius( time_span text DEFAULT NULL) RETURNS TABLE(boundary geometry, geom_refs text) AS $$ -DECLARE - circle_boundary geometry(Geometry, 4326); BEGIN - circle_boundary := ST_Buffer(geom::geography, radius)::geometry; - RETURN QUERY SELECT * FROM cdb_observatory.OBS_GetPointsByBBox( - circle_boundary, + ST_Buffer(geom::geography, radius)::geometry, boundary_id, time_span); 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' + -- TODO: filter by clipped vs. not so appropriate tablename are unique + -- so the limit 1 can be removed + LIMIT 1 + $string$, boundary_id); +END; +$$ LANGUAGE plpgsql; From 2325f9768464f49e317ce9042440fa052005294a Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Thu, 28 Apr 2016 16:33:07 -0700 Subject: [PATCH 04/15] formatting --- src/pg/sql/44_observatory_geometries.sql | 111 ++++++++++++----------- 1 file changed, 56 insertions(+), 55 deletions(-) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index af7354e..0588273 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -185,7 +185,7 @@ $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundaryById( geometry_id text, -- ex: '36047' boundary_id text, -- ex: '"us.census.tiger".county' - time_span text DEFAULT NULL --ex: '2009' + time_span text DEFAULT NULL -- ex: '2009' ) RETURNS geometry(geometry, 4326) AS $$ @@ -196,8 +196,8 @@ DECLARE geom_colname text; BEGIN -SELECT * INTO geoid_colname, target_table, geom_colname -FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id); + SELECT * INTO geoid_colname, target_table, geom_colname + FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id); RAISE NOTICE '%', target_table; @@ -258,23 +258,23 @@ DECLARE 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 contains, within, intersects)', 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; + -- 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 contains, within, intersects)', 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 --- TODO: turn this into a function _OBS_GetGeometryMetadata(geo_ref_name, tablename, and geom_colname) --- SELECT geo_ref_name, tablename, geom_colname INTO a, b, c --- FROM _OBS_GetGeometryMetadata -SELECT * INTO geoid_colname, target_table, geom_colname -FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id); + -- TODO: add timespan in search + -- TODO: add overlap info in search + -- TODO: turn this into a function _OBS_GetGeometryMetadata(geo_ref_name, tablename, and geom_colname) + -- SELECT geo_ref_name, tablename, geom_colname INTO a, b, c + -- FROM _OBS_GetGeometryMetadata + 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 @@ -377,19 +377,19 @@ DECLARE target_table text; BEGIN -IF lower(overlap_type) NOT IN ('contains', 'within', 'intersects') -THEN - RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose contains, within, intersects)', 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; + IF lower(overlap_type) NOT IN ('contains', 'within', 'intersects') + THEN + RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose contains, within, intersects)', 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); + SELECT * INTO geoid_colname, target_table, geom_colname + FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id); -RAISE NOTICE 'geoid_colname: %, target_table: %, geom_colname: %', - geoid_colname, target_table, geom_colname; + RAISE NOTICE 'geoid_colname: %, target_table: %, geom_colname: %', + geoid_colname, target_table, geom_colname; -- if no tables are found, raise notice and return null IF target_table IS NULL @@ -462,30 +462,31 @@ 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' - -- TODO: filter by clipped vs. not so appropriate tablename are unique - -- so the limit 1 can be removed - LIMIT 1 - $string$, boundary_id); + 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' + -- TODO: filter by clipped vs. not so appropriate tablename are unique + -- so the limit 1 can be removed + LIMIT 1 + $string$, boundary_id); + END; $$ LANGUAGE plpgsql; From ac3574b98b2d4592e60f0100c5676c06154af951 Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Thu, 28 Apr 2016 16:45:41 -0700 Subject: [PATCH 05/15] adding user-selected overlap methods --- src/pg/sql/44_observatory_geometries.sql | 28 +++++++++++++----------- 1 file changed, 15 insertions(+), 13 deletions(-) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index 0588273..50a239e 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -248,7 +248,8 @@ $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundariesByBBox( geom geometry(Geometry, 4326), boundary_id text, - time_span text DEFAULT NULL) + time_span text DEFAULT NULL, + overlap_type text DEFAULT 'contains') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ DECLARE @@ -290,8 +291,8 @@ BEGIN EXECUTE format( 'SELECT t.%s, t.%s FROM observatory.%s As t - WHERE ST_Contains($1, t.the_geom) - ', geom_colname, geoid_colname, target_table) + WHERE ST_%s($1, t.the_geom) + ', geom_colname, geoid_colname, target_table, overlap_type) USING geom; END; @@ -325,7 +326,8 @@ 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) + time_span text DEFAULT NULL, + overlap_type text DEFAULT 'contains') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ DECLARE @@ -367,7 +369,8 @@ $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByBBox( geom geometry(Geometry, 4326), boundary_id text, - time_span text DEFAULT NULL) + time_span text DEFAULT NULL, + overlap_type text DEFAULT 'contains') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ DECLARE @@ -379,7 +382,7 @@ BEGIN IF lower(overlap_type) NOT IN ('contains', 'within', 'intersects') THEN - RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose contains, within, intersects)', overlap_type; + RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose contains, within, or intersects)', 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); @@ -388,9 +391,6 @@ BEGIN SELECT * INTO geoid_colname, target_table, geom_colname FROM cdb_observatory._OBS_GetGeometryMetadata(boundary_id); - RAISE NOTICE 'geoid_colname: %, target_table: %, geom_colname: %', - geoid_colname, target_table, geom_colname; - -- if no tables are found, raise notice and return null IF target_table IS NULL THEN @@ -405,8 +405,8 @@ BEGIN EXECUTE format( 'SELECT ST_PointOnSurface(t.%s) As %s, t.%s FROM observatory.%s As t - WHERE ST_Contains($1, t.the_geom) - ', geom_colname, geom_colname, geoid_colname, target_table) + WHERE ST_%s($1, t.the_geom) + ', geom_colname, geom_colname, geoid_colname, target_table, overlap_type) USING geom; END; @@ -440,7 +440,8 @@ 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) + time_span text DEFAULT NULL, + overlap_type text DEFAULT 'contains') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ BEGIN @@ -449,7 +450,8 @@ BEGIN FROM cdb_observatory.OBS_GetPointsByBBox( ST_Buffer(geom::geography, radius)::geometry, boundary_id, - time_span); + time_span, + overlap_type); END; $$ LANGUAGE plpgsql; From 530ce4e61ec2b45342ffb319a87d49f7ac1dd2e3 Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Fri, 29 Apr 2016 08:52:05 -0700 Subject: [PATCH 06/15] changing overlap default to intersects --- src/pg/sql/44_observatory_geometries.sql | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index 50a239e..2bb0c13 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -249,7 +249,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundariesByBBox( geom geometry(Geometry, 4326), boundary_id text, time_span text DEFAULT NULL, - overlap_type text DEFAULT 'contains') + overlap_type text DEFAULT 'intersects') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ DECLARE @@ -327,7 +327,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundariesByPointAndRadius( radius numeric, -- radius in meters boundary_id text, time_span text DEFAULT NULL, - overlap_type text DEFAULT 'contains') + overlap_type text DEFAULT 'intersects') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ DECLARE @@ -370,7 +370,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByBBox( geom geometry(Geometry, 4326), boundary_id text, time_span text DEFAULT NULL, - overlap_type text DEFAULT 'contains') + overlap_type text DEFAULT 'intersects') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ DECLARE @@ -441,7 +441,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByPointAndRadius( radius numeric, -- radius in meters boundary_id text, time_span text DEFAULT NULL, - overlap_type text DEFAULT 'contains') + overlap_type text DEFAULT 'intersects') RETURNS TABLE(boundary geometry, geom_refs text) AS $$ BEGIN From 5168023091e1363c7b9b372aacb909b0bcb51263 Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Fri, 29 Apr 2016 14:01:36 -0700 Subject: [PATCH 07/15] adding docs for boundary functions --- doc/methods.md | 199 ++++++++++++++++++++++++++++++++++++++++++++++--- 1 file changed, 187 insertions(+), 12 deletions(-) diff --git a/doc/methods.md b/doc/methods.md index 43bf5a4..8f98281 100644 --- a/doc/methods.md +++ b/doc/methods.md @@ -84,7 +84,7 @@ Should add the SQL API call here too ## OBS_GetUSCensusCategory(point_geometry, measure_name); -The ```OBS_GetUSCensusCategory(point_geometry, category_name)``` method returns a categorical measure based on a subset of the US Census variables at a point location. It requires a different function from ```OBS_GetUSCensusMeasure``` because this function will always return TEXT, whereas ```OBS_GetUSCensusMeasure``` will always returna NUMERIC value. +The ```OBS_GetUSCensusCategory(point_geometry, category_name)``` method returns a categorical measure based on a subset of the US Census variables at a point location. It requires a different function from ```OBS_GetUSCensusMeasure``` because this function will always return TEXT, whereas ```OBS_GetUSCensusMeasure``` will always returna NUMERIC value. #### Arguments @@ -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 @@ -224,22 +224,22 @@ 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') ``` -## 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) #### Returns @@ -253,12 +253,13 @@ 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) -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)``` 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 @@ -279,7 +280,181 @@ geom | a WGS84 polygon geometry Use a table of geometry_id to select the unique boundaries. Useful with the ```Table 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) the_geom, geometry_id FROM tablename GROUP BY geometry_id +``` + +## OBS_GetBoundariesByBBox(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. + +#### 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) or [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.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_GetBoundariesByBBox( + 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_GetBoundariesByBBox(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) + +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). + +#### 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) or [ST_Contains](http://postgis.net/docs/manual-2.2/ST_Contains.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_GetPointsByBBox( + 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_GetPointsByBBox(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 +474,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) From 7556e43b22d168028202ce2551347f2c9273e12b Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Fri, 29 Apr 2016 14:02:00 -0700 Subject: [PATCH 08/15] change return name of boundaries to the_geom --- src/pg/sql/44_observatory_geometries.sql | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index 2bb0c13..5be8cde 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -250,7 +250,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundariesByBBox( boundary_id text, time_span text DEFAULT NULL, overlap_type text DEFAULT 'intersects') -RETURNS TABLE(boundary geometry, geom_refs text) +RETURNS TABLE(the_geom geometry, geom_refs text) AS $$ DECLARE boundary geometry(Geometry, 4326); @@ -328,7 +328,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetBoundariesByPointAndRadius( boundary_id text, time_span text DEFAULT NULL, overlap_type text DEFAULT 'intersects') -RETURNS TABLE(boundary geometry, geom_refs text) +RETURNS TABLE(the_geom geometry, geom_refs text) AS $$ DECLARE circle_boundary geometry(Geometry, 4326); @@ -371,7 +371,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByBBox( boundary_id text, time_span text DEFAULT NULL, overlap_type text DEFAULT 'intersects') -RETURNS TABLE(boundary geometry, geom_refs text) +RETURNS TABLE(the_geom geometry, geom_refs text) AS $$ DECLARE boundary geometry(Geometry, 4326); @@ -442,7 +442,7 @@ CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetPointsByPointAndRadius( boundary_id text, time_span text DEFAULT NULL, overlap_type text DEFAULT 'intersects') -RETURNS TABLE(boundary geometry, geom_refs text) +RETURNS TABLE(the_geom geometry, geom_refs text) AS $$ BEGIN From 57fe6862b07569d7e52ccae06f604b28a20cd396 Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Mon, 2 May 2016 08:55:01 -0400 Subject: [PATCH 09/15] small edits --- src/pg/sql/44_observatory_geometries.sql | 27 ++++++++++++++++++------ 1 file changed, 20 insertions(+), 7 deletions(-) diff --git a/src/pg/sql/44_observatory_geometries.sql b/src/pg/sql/44_observatory_geometries.sql index 5be8cde..6f9720d 100644 --- a/src/pg/sql/44_observatory_geometries.sql +++ b/src/pg/sql/44_observatory_geometries.sql @@ -263,7 +263,7 @@ BEGIN 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 contains, within, intersects)', overlap_type; + 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); @@ -321,7 +321,7 @@ $$ LANGUAGE plpgsql; -- 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 @@ -334,7 +334,12 @@ DECLARE circle_boundary geometry(Geometry, 4326); BEGIN - circle_boundary := ST_Buffer(geom::geography, radius)::geometry; + 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_GetBoundariesByBBox( @@ -382,7 +387,7 @@ BEGIN IF lower(overlap_type) NOT IN ('contains', 'within', 'intersects') THEN - RAISE EXCEPTION 'Overlap type ''%'' is not an accepted type (choose contains, within, or intersects)', overlap_type; + 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); @@ -446,6 +451,13 @@ RETURNS TABLE(the_geom geometry, geom_refs text) AS $$ 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_GetPointsByBBox( ST_Buffer(geom::geography, radius)::geometry, @@ -481,10 +493,11 @@ BEGIN 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 + 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' + -- 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 LIMIT 1 From c5a49ade605b9fb6ae80c084cceabd602854508e Mon Sep 17 00:00:00 2001 From: Andy Eschbacher Date: Mon, 2 May 2016 09:53:30 -0400 Subject: [PATCH 10/15] updates to docs descriptions --- doc/methods.md | 23 +++++++++++++++-------- 1 file changed, 15 insertions(+), 8 deletions(-) diff --git a/doc/methods.md b/doc/methods.md index 8f98281..f666695 100644 --- a/doc/methods.md +++ b/doc/methods.md @@ -211,7 +211,8 @@ The ```OBS_GetBoundary(point_geometry, boundary_id)``` method returns a boundary Name | Description --- | --- point_geometry | a WGS84 polygon geometry (the_geom) -boundary_id | a boundary identifier from the [Boundary ID glossary table below](below) +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,7 +225,8 @@ geom | WKB geometry Overwrite a point geometry with a boundary geometry that contains it in your table ```SQL -UPDATE tablename SET the_geom = OBS_GetBoundary(the_geom, ' "us.census.tiger".block_group') +UPDATE tablename +SET the_geom = OBS_GetBoundary(the_geom, '"us.census.tiger".block_group') ```