new code to handle mixed geometries more quickly
This commit is contained in:
parent
183c046289
commit
6266262427
@ -166,28 +166,15 @@ BEGIN
|
|||||||
|
|
||||||
EXECUTE format($string$
|
EXECUTE format($string$
|
||||||
WITH _filters AS (SELECT
|
WITH _filters AS (SELECT
|
||||||
generate_series(1, array_length($3, 1)) id,
|
row_number() over () id, *
|
||||||
(unnest($3))->>'numer_id' numer_id,
|
FROM json_to_recordset($3)
|
||||||
(unnest($3))->>'denom_id' denom_id,
|
AS x(numer_id TEXT, denom_id TEXT, geom_id TEXT, numer_timespan TEXT,
|
||||||
(unnest($3))->>'geom_id' geom_id,
|
geom_timespan TEXT, normalization TEXT, max_timespan_rank TEXT,
|
||||||
(unnest($3))->>'numer_timespan' numer_timespan,
|
max_score_rank TEXT, target_geoms INTEGER, target_area Numeric
|
||||||
(unnest($3))->>'geom_timespan' geom_timespan,
|
)
|
||||||
(unnest($3))->>'normalization' normalization,
|
|
||||||
(unnest($3))->>'max_timespan_rank' max_timespan_rank,
|
|
||||||
(unnest($3))->>'max_score_rank' max_score_rank,
|
|
||||||
((unnest($3))->>'target_geoms')::INTEGER target_geoms,
|
|
||||||
((unnest($3))->>'target_area')::Numeric target_area
|
|
||||||
), meta AS (SELECT
|
), meta AS (SELECT
|
||||||
id,
|
id,
|
||||||
f.numer_id,
|
f.numer_id,
|
||||||
LOWER(TRIM(BOTH '_' FROM regexp_replace(CASE WHEN f.numer_id IS NOT NULL
|
|
||||||
THEN CASE
|
|
||||||
WHEN normalization ILIKE 'area%%' THEN numer_colname || ' per sq km'
|
|
||||||
WHEN normalization ILIKE 'denom%%' THEN numer_colname || ' rate'
|
|
||||||
ELSE numer_colname
|
|
||||||
END || ' ' || m.numer_timespan
|
|
||||||
ELSE geom_name || ' ' || m.geom_timespan
|
|
||||||
END, '[^a-zA-Z0-9]+', '_', 'g'))) suggested_name,
|
|
||||||
CASE WHEN f.numer_id IS NULL THEN NULL ELSE numer_aggregate END numer_aggregate,
|
CASE WHEN f.numer_id IS NULL THEN NULL ELSE numer_aggregate END numer_aggregate,
|
||||||
CASE WHEN f.numer_id IS NULL THEN NULL ELSE numer_colname END numer_colname,
|
CASE WHEN f.numer_id IS NULL THEN NULL ELSE numer_colname END numer_colname,
|
||||||
CASE WHEN f.numer_id IS NULL THEN NULL ELSE numer_geomref_colname END numer_geomref_colname,
|
CASE WHEN f.numer_id IS NULL THEN NULL ELSE numer_geomref_colname END numer_geomref_colname,
|
||||||
@ -217,7 +204,17 @@ BEGIN
|
|||||||
geom_description,
|
geom_description,
|
||||||
geom_t_description,
|
geom_t_description,
|
||||||
geom_type,
|
geom_type,
|
||||||
normalization,
|
Coalesce(normalization,
|
||||||
|
-- automatically assign normalization to numeric numerators
|
||||||
|
CASE WHEN cdb_observatory.isnumeric(numer_type) THEN
|
||||||
|
CASE WHEN denom_reltype ILIKE 'denominator' THEN 'denominated'
|
||||||
|
WHEN numer_aggregate ILIKE 'sum' THEN 'area'
|
||||||
|
WHEN numer_aggregate IN ('median', 'average') AND denom_reltype ILIKE 'universe'
|
||||||
|
THEN 'prenormalized'
|
||||||
|
ELSE 'prenormalized'
|
||||||
|
END ELSE NULL
|
||||||
|
END
|
||||||
|
) normalization,
|
||||||
max_timespan_rank,
|
max_timespan_rank,
|
||||||
max_score_rank,
|
max_score_rank,
|
||||||
target_geoms,
|
target_geoms,
|
||||||
@ -249,7 +246,16 @@ BEGIN
|
|||||||
'score_rownum', row_number() over
|
'score_rownum', row_number() over
|
||||||
(PARTITION BY id, numer_timespan ORDER BY score DESC, Coalesce(denom_id, '')),
|
(PARTITION BY id, numer_timespan ORDER BY score DESC, Coalesce(denom_id, '')),
|
||||||
'score', scores.score,
|
'score', scores.score,
|
||||||
'suggested_name', cdb_observatory.FIRST(meta.suggested_name),
|
'suggested_name', cdb_observatory.FIRST(
|
||||||
|
LOWER(TRIM(BOTH '_' FROM regexp_replace(CASE WHEN numer_id IS NOT NULL
|
||||||
|
THEN CASE
|
||||||
|
WHEN normalization ILIKE 'area%%' THEN numer_colname || ' per sq km'
|
||||||
|
WHEN normalization ILIKE 'denom%%' THEN numer_colname || ' rate'
|
||||||
|
ELSE numer_colname
|
||||||
|
END || ' ' || numer_timespan
|
||||||
|
ELSE geom_name || ' ' || geom_timespan
|
||||||
|
END, '[^a-zA-Z0-9]+', '_', 'g')))
|
||||||
|
),
|
||||||
'numer_aggregate', cdb_observatory.FIRST(meta.numer_aggregate),
|
'numer_aggregate', cdb_observatory.FIRST(meta.numer_aggregate),
|
||||||
'numer_colname', cdb_observatory.FIRST(meta.numer_colname),
|
'numer_colname', cdb_observatory.FIRST(meta.numer_colname),
|
||||||
'numer_geomref_colname', cdb_observatory.FIRST(meta.numer_geomref_colname),
|
'numer_geomref_colname', cdb_observatory.FIRST(meta.numer_geomref_colname),
|
||||||
@ -305,7 +311,7 @@ BEGIN
|
|||||||
ELSE geom
|
ELSE geom
|
||||||
END,
|
END,
|
||||||
target_geoms,
|
target_geoms,
|
||||||
(SELECT ARRAY(SELECT json_array_elements_text(params))::json[]),
|
params,
|
||||||
num_timespan_options,
|
num_timespan_options,
|
||||||
num_score_options, numer_filters, geom_filters
|
num_score_options, numer_filters, geom_filters
|
||||||
;
|
;
|
||||||
@ -587,14 +593,9 @@ RETURNS TABLE (
|
|||||||
)
|
)
|
||||||
AS $$
|
AS $$
|
||||||
DECLARE
|
DECLARE
|
||||||
geom_colspecs TEXT;
|
procgeom_clauses TEXT;
|
||||||
geom_tables TEXT;
|
val_clauses TEXT;
|
||||||
geomrefs_alias TEXT;
|
json_clause TEXT;
|
||||||
geomrefs_noalias TEXT;
|
|
||||||
data_colspecs TEXT;
|
|
||||||
data_tables TEXT;
|
|
||||||
obs_wheres TEXT;
|
|
||||||
user_wheres TEXT;
|
|
||||||
geomtype TEXT;
|
geomtype TEXT;
|
||||||
BEGIN
|
BEGIN
|
||||||
IF params IS NULL OR JSON_ARRAY_LENGTH(params) = 0 OR ARRAY_LENGTH(geomvals, 1) IS NULL THEN
|
IF params IS NULL OR JSON_ARRAY_LENGTH(params) = 0 OR ARRAY_LENGTH(geomvals, 1) IS NULL THEN
|
||||||
@ -604,222 +605,211 @@ BEGIN
|
|||||||
|
|
||||||
geomtype := ST_GeometryType(geomvals[1].geom);
|
geomtype := ST_GeometryType(geomvals[1].geom);
|
||||||
|
|
||||||
EXECUTE
|
/* Read metadata to generate clauses for query */
|
||||||
$query$
|
EXECUTE $query$
|
||||||
WITH _meta AS (SELECT
|
WITH _meta AS (SELECT
|
||||||
row_number() over () colid,
|
row_number() over () colid, *
|
||||||
meta->>'id' id,
|
FROM json_to_recordset($1)
|
||||||
meta->>'numer_id' numer_id,
|
AS x(id TEXT, numer_id TEXT, numer_aggregate TEXT, numer_colname TEXT,
|
||||||
meta->>'numer_aggregate' numer_aggregate,
|
numer_geomref_colname TEXT, numer_tablename TEXT, numer_type TEXT,
|
||||||
meta->>'numer_colname' numer_colname,
|
denom_id TEXT, denom_aggregate TEXT, denom_colname TEXT,
|
||||||
meta->>'numer_geomref_colname' numer_geomref_colname,
|
denom_geomref_colname TEXT, denom_tablename TEXT, denom_type TEXT,
|
||||||
meta->>'numer_tablename' numer_tablename,
|
denom_reltype TEXT, geom_id TEXT, geom_colname TEXT,
|
||||||
meta->>'numer_type' numer_type,
|
geom_geomref_colname TEXT, geom_tablename TEXT, geom_type TEXT,
|
||||||
meta->>'denom_id' denom_id,
|
numer_timespan TEXT, geom_timespan TEXT, normalization TEXT,
|
||||||
meta->>'denom_aggregate' denom_aggregate,
|
api_method TEXT, api_args JSON)
|
||||||
meta->>'denom_colname' denom_colname,
|
),
|
||||||
meta->>'denom_geomref_colname' denom_geomref_colname,
|
|
||||||
meta->>'denom_tablename' denom_tablename,
|
-- Generate procgeom clauses.
|
||||||
meta->>'denom_type' denom_type,
|
-- These join the users' geoms to the relevant geometries for the
|
||||||
meta->>'denom_reltype' denom_reltype,
|
-- asked-for measures in the Observatory.
|
||||||
meta->>'geom_id' geom_id,
|
_procgeom_clauses AS (
|
||||||
meta->>'geom_colname' geom_colname,
|
|
||||||
meta->>'geom_geomref_colname' geom_geomref_colname,
|
|
||||||
meta->>'geom_tablename' geom_tablename,
|
|
||||||
meta->>'geom_type' geom_type,
|
|
||||||
meta->>'numer_timespan' numer_timespan,
|
|
||||||
meta->>'geom_timespan' geom_timespan,
|
|
||||||
meta->>'normalization' normalization,
|
|
||||||
meta->>'api_method' api_method,
|
|
||||||
meta->'api_args' api_args
|
|
||||||
FROM UNNEST($1) AS meta
|
|
||||||
)
|
|
||||||
SELECT
|
SELECT
|
||||||
String_Agg(DISTINCT
|
'_procgeoms_' || Coalesce(geom_tablename || '_' || geom_geomref_colname, api_method) || ' AS (' ||
|
||||||
CASE
|
CASE WHEN api_method IS NULL THEN
|
||||||
-- pass-through geom if user is requesting it only
|
'SELECT _geoms.id, ' ||
|
||||||
WHEN numer_id IS NULL AND api_method IS NULL THEN
|
CASE $3 WHEN True THEN '_geoms.geom'
|
||||||
geom_tablename || '.' || geom_colname || ' AS geom_' || geom_tablename
|
ELSE geom_tablename || '.' || geom_colname
|
||||||
WHEN cdb_observatory.isnumeric(numer_type) AND api_method IS NULL THEN
|
END || ' AS geom, ' ||
|
||||||
-- for numeric points with area normalization, include areas of underlying geoms
|
geom_tablename || '.' || geom_geomref_colname || ' AS geomref, ' ||
|
||||||
CASE
|
CASE
|
||||||
WHEN $2 = 'ST_Point' AND (LOWER(normalization) LIKE 'area%' OR
|
WHEN $2 = 'ST_Point' THEN
|
||||||
(normalization IS NULL AND numer_aggregate ILIKE 'sum')) THEN
|
' Nullif(ST_Area(' || geom_tablename || '.' || geom_colname || '::Geography), 0)/1000000 ' ||
|
||||||
' Nullif(ST_Area(' || geom_tablename || '.' || geom_colname || '::Geography), 0)/1000000 ' ||
|
' AS area'
|
||||||
' AS area_' || geom_tablename
|
-- for numeric areas, include more complex calcs
|
||||||
-- for numeric areas, include more complex calcs
|
ELSE
|
||||||
WHEN $2 != 'ST_Point' THEN
|
'CASE WHEN ST_Within(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ')
|
||||||
'CASE WHEN ST_Within(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ') ' ||
|
THEN ST_Area(_geoms.geom) / Nullif(ST_Area(' || geom_tablename || '.' || geom_colname || '), 0)
|
||||||
' THEN ST_Area(_geoms.geom) / Nullif(ST_Area(' || geom_tablename || '.' || geom_colname || '), 0)' ||
|
WHEN ST_Within(' || geom_tablename || '.' || geom_colname || ', _geoms.geom)
|
||||||
' WHEN ST_Within(' || geom_tablename || '.' || geom_colname || ', _geoms.geom) ' ||
|
THEN 1
|
||||||
' THEN 1 ' ||
|
ELSE ST_Area(cdb_observatory.safe_intersection(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ')) /
|
||||||
' ELSE ST_Area(cdb_observatory.safe_intersection(_geoms.geom, ' ||
|
Nullif(ST_Area(' || geom_tablename || '.' || geom_colname || '), 0)
|
||||||
geom_tablename || '.' || geom_colname || ')) / ' ||
|
END pct_obs'
|
||||||
'Nullif(ST_Area(' || geom_tablename || '.' || geom_colname || '), 0) ' ||
|
END || '
|
||||||
'END pct_' || geom_tablename
|
FROM _geoms, observatory.' || geom_tablename || '
|
||||||
ELSE NULL
|
WHERE ST_Intersects(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ')'
|
||||||
END
|
-- pass through input geometries for api_method
|
||||||
ELSE NULL END
|
ELSE 'SELECT _geoms.id, _geoms.geom FROM _geoms'
|
||||||
, ', ') AS geom_colspecs,
|
END ||
|
||||||
String_Agg(DISTINCT 'observatory.' || geom_tablename, ', ') AS geom_tables,
|
') '
|
||||||
String_Agg(
|
AS procgeom_clause
|
||||||
'JSON_Build_Object(' || CASE
|
|
||||||
-- api-delivered values
|
|
||||||
WHEN api_method IS NOT NULL THEN
|
|
||||||
'''value'', ' ||
|
|
||||||
'ARRAY_AGG( ' ||
|
|
||||||
api_method || '.' || numer_colname || ')::' || numer_type || '[]'
|
|
||||||
-- numeric internal values
|
|
||||||
WHEN cdb_observatory.isnumeric(numer_type) THEN
|
|
||||||
'''value'', ' || CASE
|
|
||||||
-- denominated
|
|
||||||
WHEN LOWER(normalization) LIKE 'denom%' OR
|
|
||||||
(normalization IS NULL AND LOWER(denom_reltype) LIKE 'denominator')
|
|
||||||
THEN CASE
|
|
||||||
-- denominated point-in-poly
|
|
||||||
WHEN $2 = 'ST_Point' THEN
|
|
||||||
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname ||
|
|
||||||
' / NullIf(' || denom_tablename || '.' || denom_colname || ', 0))'
|
|
||||||
-- denominated polygon interpolation
|
|
||||||
-- SUM (numer * (% OBS geom in user geom)) / SUM (denom * (% OBS geom in user geom))
|
|
||||||
ELSE
|
|
||||||
' SUM(' || numer_tablename || '.' || numer_colname || ' ' ||
|
|
||||||
' * pct_' || geom_tablename ||
|
|
||||||
' ) / NULLIF(SUM(' || denom_tablename || '.' || denom_colname || ' ' ||
|
|
||||||
' * pct_' || geom_tablename || '), 0) ' ||
|
|
||||||
' / (COUNT(*) / COUNT(distinct geomref_' || geom_tablename || ')) '
|
|
||||||
END
|
|
||||||
-- areaNormalized
|
|
||||||
WHEN LOWER(normalization) LIKE 'area%' OR
|
|
||||||
(normalization IS NULL AND numer_aggregate ILIKE 'sum')
|
|
||||||
THEN CASE
|
|
||||||
-- areaNormalized point-in-poly
|
|
||||||
WHEN $2 = 'ST_Point' THEN
|
|
||||||
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname ||
|
|
||||||
' / area_' || geom_tablename || ')'
|
|
||||||
-- areaNormalized polygon interpolation
|
|
||||||
-- SUM (numer * (% OBS geom in user geom)) / area of big geom
|
|
||||||
ELSE
|
|
||||||
--' NULL END '
|
|
||||||
' SUM(' || numer_tablename || '.' || numer_colname || ' ' ||
|
|
||||||
' * pct_' || geom_tablename ||
|
|
||||||
' ) / (Nullif(ST_Area(cdb_observatory.FIRST(_procgeoms.geom)::Geography), 0) / 1000000) ' ||
|
|
||||||
' / (COUNT(*) / COUNT(distinct geomref_' || geom_tablename || ')) '
|
|
||||||
END
|
|
||||||
-- median/average measures with universe
|
|
||||||
WHEN LOWER(numer_aggregate) IN ('median', 'average') AND
|
|
||||||
denom_reltype ILIKE 'universe' AND
|
|
||||||
(normalization IS NULL OR LOWER(normalization) LIKE 'pre%')
|
|
||||||
THEN CASE
|
|
||||||
-- predenominated point-in-poly
|
|
||||||
WHEN $2 = 'ST_Point' THEN
|
|
||||||
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname || ') '
|
|
||||||
ELSE
|
|
||||||
-- predenominated polygon interpolation weighted by universe
|
|
||||||
-- SUM (numer * denom * (% user geom in OBS geom)) / SUM (denom * (% user geom in OBS geom))
|
|
||||||
-- (10 * 1000 * 1) / (1000 * 1) = 10
|
|
||||||
-- (10 * 1000 * 1 + 50 * 10 * 1) / (1000 + 10) = 10500 / 10000 = 10.5
|
|
||||||
' SUM(' || numer_tablename || '.' || numer_colname ||
|
|
||||||
' * ' || denom_tablename || '.' || denom_colname ||
|
|
||||||
' * pct_' || geom_tablename ||
|
|
||||||
' ) / Nullif(SUM(' || denom_tablename || '.' || denom_colname ||
|
|
||||||
' * pct_' || geom_tablename || '), 0) ' ||
|
|
||||||
' / (COUNT(*) / COUNT(distinct geomref_' || geom_tablename || ')) '
|
|
||||||
END
|
|
||||||
-- prenormalized for summable measures. point or summable only!
|
|
||||||
WHEN numer_aggregate ILIKE 'sum' AND
|
|
||||||
(normalization IS NULL OR LOWER(normalization) LIKE 'pre%')
|
|
||||||
THEN CASE
|
|
||||||
-- predenominated point-in-poly
|
|
||||||
WHEN $2 = 'ST_Point' THEN
|
|
||||||
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname || ') '
|
|
||||||
ELSE
|
|
||||||
-- predenominated polygon interpolation
|
|
||||||
-- SUM (numer * (% user geom in OBS geom))
|
|
||||||
' SUM(' || numer_tablename || '.' || numer_colname || ' ' ||
|
|
||||||
' * pct_' || geom_tablename ||
|
|
||||||
' ) / (COUNT(*) / COUNT(distinct geomref_' || geom_tablename || ')) '
|
|
||||||
END
|
|
||||||
-- Everything else. Point only!
|
|
||||||
ELSE CASE
|
|
||||||
WHEN $2 = 'ST_Point' THEN
|
|
||||||
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname || ') '
|
|
||||||
ELSE
|
|
||||||
' cdb_observatory._OBS_RaiseNotice(''Cannot perform calculation over polygon for ' ||
|
|
||||||
numer_id || '/' || coalesce(denom_id, '') || '/' || geom_id || '/' || numer_timespan || ''')::Numeric '
|
|
||||||
END
|
|
||||||
END || '::' || numer_type
|
|
||||||
|
|
||||||
-- categorical/text
|
|
||||||
WHEN LOWER(numer_type) LIKE 'text' THEN
|
|
||||||
'''value'', ' || 'MODE() WITHIN GROUP (ORDER BY ' || numer_tablename || '.' || numer_colname || ') '
|
|
||||||
|
|
||||||
-- geometry
|
|
||||||
WHEN numer_id IS NULL THEN
|
|
||||||
'''geomref'', geomref_' || geom_tablename || ', ' ||
|
|
||||||
'''value'', ' || 'cdb_observatory.FIRST(geom_' || geom_tablename ||
|
|
||||||
')::TEXT'
|
|
||||||
-- code below will return the intersection of the user's geom and the
|
|
||||||
-- OBS geom
|
|
||||||
--'''value'', ' || 'ST_Union(cdb_observatory.safe_intersection(_geoms.geom, ' || geom_tablename ||
|
|
||||||
-- '.' || geom_colname || '))::TEXT'
|
|
||||||
ELSE ''
|
|
||||||
END || ')', ', ')
|
|
||||||
AS colspecs,
|
|
||||||
|
|
||||||
-- geomrefs, used to separate out rows in case we don't want to merge
|
|
||||||
-- results by user input IDs
|
|
||||||
--
|
|
||||||
-- api_method and geom_tablename are interchangeable since when an
|
|
||||||
-- api_method is passed, geom_tablename is ignored
|
|
||||||
String_Agg(DISTINCT COALESCE(geom_tablename, api_method) || '.' || geom_geomref_colname ||
|
|
||||||
' AS geomref_' || COALESCE(geom_tablename, api_method), ', ') AS geomrefs_alias,
|
|
||||||
|
|
||||||
String_Agg(DISTINCT 'geomref_' || COALESCE(geom_tablename, api_method)
|
|
||||||
, ', ') AS geomrefs_noalias,
|
|
||||||
|
|
||||||
(SELECT String_Agg(DISTINCT CASE
|
|
||||||
-- External API
|
|
||||||
WHEN tablename LIKE 'cdb_observatory.%' THEN
|
|
||||||
'LATERAL (SELECT * FROM ' || tablename || ') ' ||
|
|
||||||
REPLACE(split_part(tablename, '(', 1), 'cdb_observatory.', '')
|
|
||||||
-- Internal obs_ table
|
|
||||||
ELSE 'observatory.' || tablename
|
|
||||||
END, ', ') FROM (
|
|
||||||
SELECT DISTINCT UNNEST(tablenames_ary) tablename FROM (
|
|
||||||
SELECT ARRAY_AGG(numer_tablename) ||
|
|
||||||
ARRAY_AGG(denom_tablename) ||
|
|
||||||
ARRAY_AGG('cdb_observatory.' || api_method || '(_procgeoms.geom' || COALESCE(', ' ||
|
|
||||||
(SELECT STRING_AGG(REPLACE(val::text, '"', ''''), ', ')
|
|
||||||
FROM (SELECT json_array_elements(api_args) as val) as vals),
|
|
||||||
'') || ')')
|
|
||||||
tablenames_ary
|
|
||||||
) tablenames_inner
|
|
||||||
) tablenames_outer) data_tables,
|
|
||||||
|
|
||||||
String_Agg(DISTINCT array_to_string(ARRAY[
|
|
||||||
CASE WHEN numer_tablename IS NOT NULL AND geom_tablename IS NOT NULL
|
|
||||||
THEN numer_tablename || '.' || numer_geomref_colname || ' = ' ||
|
|
||||||
'_procgeoms.geomref_' || geom_tablename
|
|
||||||
ELSE NULL END,
|
|
||||||
CASE WHEN numer_tablename != denom_tablename
|
|
||||||
THEN numer_tablename || '.' || numer_geomref_colname || ' = ' ||
|
|
||||||
denom_tablename || '.' || denom_geomref_colname
|
|
||||||
ELSE NULL END
|
|
||||||
], ' AND '),
|
|
||||||
' AND ') FILTER (WHERE numer_tablename != denom_tablename OR
|
|
||||||
(numer_tablename IS NOT NULL AND geom_tablename IS NOT NULL)) AS obs_wheres,
|
|
||||||
|
|
||||||
String_Agg(DISTINCT 'ST_Intersects(' || geom_tablename || '.' || geom_colname
|
|
||||||
|| ', _geoms.geom)', ' AND ')
|
|
||||||
AS user_wheres
|
|
||||||
FROM _meta
|
FROM _meta
|
||||||
;
|
GROUP BY api_method, geom_tablename, geom_geomref_colname, geom_colname
|
||||||
$query$
|
),
|
||||||
INTO geom_colspecs, geom_tables, data_colspecs, geomrefs_alias,
|
|
||||||
geomrefs_noalias, data_tables, obs_wheres, user_wheres
|
|
||||||
USING (SELECT ARRAY(SELECT json_array_elements_text(params))::json[]), geomtype;
|
|
||||||
|
|
||||||
|
-- Generate val clauses.
|
||||||
|
-- These perform interpolations or other necessary calculations to
|
||||||
|
-- provide values according to users geometries.
|
||||||
|
_val_clauses AS (
|
||||||
|
SELECT
|
||||||
|
'_vals_' || Coalesce(geom_tablename || '_' || geom_geomref_colname, api_method) || ' AS (
|
||||||
|
SELECT _procgeoms.id, ' ||
|
||||||
|
String_Agg('json_build_object(' || CASE
|
||||||
|
-- api-delivered values
|
||||||
|
WHEN api_method IS NOT NULL THEN
|
||||||
|
'''value'', ' ||
|
||||||
|
'ARRAY_AGG( ' ||
|
||||||
|
api_method || '.' || numer_colname || ')::' || numer_type || '[]'
|
||||||
|
-- numeric internal values
|
||||||
|
WHEN cdb_observatory.isnumeric(numer_type) THEN
|
||||||
|
'''value'', ' || CASE
|
||||||
|
-- denominated
|
||||||
|
WHEN LOWER(normalization) LIKE 'denom%'
|
||||||
|
THEN CASE
|
||||||
|
WHEN denom_tablename IS NULL THEN ' NULL '
|
||||||
|
-- denominated point-in-poly
|
||||||
|
WHEN $2 = 'ST_Point' THEN
|
||||||
|
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname ||
|
||||||
|
' / NullIf(' || denom_tablename || '.' || denom_colname || ', 0))'
|
||||||
|
-- denominated polygon interpolation
|
||||||
|
-- SUM (numer * (% OBS geom in user geom)) / SUM (denom * (% OBS geom in user geom))
|
||||||
|
ELSE
|
||||||
|
' SUM(' || numer_tablename || '.' || numer_colname || ' ' ||
|
||||||
|
' * _procgeoms.pct_obs ' ||
|
||||||
|
' ) / NULLIF(SUM(' || denom_tablename || '.' || denom_colname || ' ' ||
|
||||||
|
' * _procgeoms.pct_obs), 0) '
|
||||||
|
END
|
||||||
|
-- areaNormalized
|
||||||
|
WHEN LOWER(normalization) LIKE 'area%'
|
||||||
|
THEN CASE
|
||||||
|
-- areaNormalized point-in-poly
|
||||||
|
WHEN $2 = 'ST_Point' THEN
|
||||||
|
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname ||
|
||||||
|
' / _procgeoms.area)'
|
||||||
|
-- areaNormalized polygon interpolation
|
||||||
|
-- SUM (numer * (% OBS geom in user geom)) / area of big geom
|
||||||
|
ELSE
|
||||||
|
--' NULL END '
|
||||||
|
' SUM(' || numer_tablename || '.' || numer_colname || ' ' ||
|
||||||
|
' * _procgeoms.pct_obs' ||
|
||||||
|
' ) / (Nullif(ST_Area(cdb_observatory.FIRST(_procgeoms.geom)::Geography), 0) / 1000000) '
|
||||||
|
END
|
||||||
|
-- median/average measures with universe
|
||||||
|
WHEN LOWER(numer_aggregate) IN ('median', 'average') AND
|
||||||
|
denom_reltype ILIKE 'universe' AND LOWER(normalization) LIKE 'pre%'
|
||||||
|
THEN CASE
|
||||||
|
-- predenominated point-in-poly
|
||||||
|
WHEN $2 = 'ST_Point' THEN
|
||||||
|
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname || ') '
|
||||||
|
ELSE
|
||||||
|
-- predenominated polygon interpolation weighted by universe
|
||||||
|
-- SUM (numer * denom * (% user geom in OBS geom)) / SUM (denom * (% user geom in OBS geom))
|
||||||
|
-- (10 * 1000 * 1) / (1000 * 1) = 10
|
||||||
|
-- (10 * 1000 * 1 + 50 * 10 * 1) / (1000 + 10) = 10500 / 10000 = 10.5
|
||||||
|
' SUM(' || numer_tablename || '.' || numer_colname ||
|
||||||
|
' * ' || denom_tablename || '.' || denom_colname ||
|
||||||
|
' * _procgeoms.pct_obs ' ||
|
||||||
|
' ) / Nullif(SUM(' || denom_tablename || '.' || denom_colname ||
|
||||||
|
' * _procgeoms.pct_obs ' || '), 0) '
|
||||||
|
END
|
||||||
|
-- prenormalized for summable measures. point or summable only!
|
||||||
|
WHEN numer_aggregate ILIKE 'sum' AND LOWER(normalization) LIKE 'pre%'
|
||||||
|
THEN CASE
|
||||||
|
-- predenominated point-in-poly
|
||||||
|
WHEN $2 = 'ST_Point' THEN
|
||||||
|
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname || ') '
|
||||||
|
ELSE
|
||||||
|
-- predenominated polygon interpolation
|
||||||
|
-- SUM (numer * (% user geom in OBS geom))
|
||||||
|
' SUM(' || numer_tablename || '.' || numer_colname || ' ' ||
|
||||||
|
' * _procgeoms.pct_obs) '
|
||||||
|
END
|
||||||
|
-- Everything else. Point only!
|
||||||
|
ELSE CASE
|
||||||
|
WHEN $2 = 'ST_Point' THEN
|
||||||
|
' cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname || ') '
|
||||||
|
ELSE
|
||||||
|
' cdb_observatory._OBS_RaiseNotice(''Cannot perform calculation over polygon for ' ||
|
||||||
|
numer_id || '/' || coalesce(denom_id, '') || '/' || geom_id || '/' || numer_timespan || ''')::Numeric '
|
||||||
|
END
|
||||||
|
END || '::' || numer_type
|
||||||
|
|
||||||
|
-- categorical/text
|
||||||
|
WHEN LOWER(numer_type) LIKE 'text' THEN
|
||||||
|
'''value'', ' || 'MODE() WITHIN GROUP (ORDER BY ' || numer_tablename || '.' || numer_colname || ') '
|
||||||
|
-- geometry
|
||||||
|
WHEN numer_id IS NULL THEN
|
||||||
|
'''geomref'', _procgeoms.geomref, ' ||
|
||||||
|
'''value'', ' || 'cdb_observatory.FIRST(_procgeoms.geom)::TEXT'
|
||||||
|
-- code below will return the intersection of the user's geom and the
|
||||||
|
-- OBS geom
|
||||||
|
--'''value'', ' || 'ST_Union(cdb_observatory.safe_intersection(_geoms.geom, ' || geom_tablename ||
|
||||||
|
-- '.' || geom_colname || '))::TEXT'
|
||||||
|
ELSE ''
|
||||||
|
END
|
||||||
|
|| ') val_' || colid, ', ')
|
||||||
|
|| '
|
||||||
|
FROM _procgeoms_' || Coalesce(geom_tablename || '_' || geom_geomref_colname, api_method) || ' _procgeoms ' ||
|
||||||
|
Coalesce(', ' || String_Agg(DISTINCT
|
||||||
|
Coalesce('observatory.' || numer_tablename,
|
||||||
|
'LATERAL (SELECT * FROM cdb_observatory.' || api_method || '(_procgeoms.geom' || Coalesce(', ' ||
|
||||||
|
(SELECT STRING_AGG(REPLACE(val::text, '"', ''''), ', ')
|
||||||
|
FROM (SELECT JSON_Array_Elements(api_args) as val) as vals),
|
||||||
|
'') || ')) AS ' || api_method)
|
||||||
|
, ', '), '') ||
|
||||||
|
Coalesce(' WHERE ' || String_Agg(DISTINCT
|
||||||
|
'_procgeoms.geomref = ' || numer_tablename || '.' || numer_geomref_colname, ' AND '
|
||||||
|
), '') ||
|
||||||
|
CASE $3 WHEN True THEN E'\n GROUP BY _procgeoms.id ORDER BY _procgeoms.id '
|
||||||
|
ELSE E'\n GROUP BY _procgeoms.id, _procgeoms.geomref
|
||||||
|
ORDER BY _procgeoms.id, _procgeoms.geomref' END
|
||||||
|
|| ')'
|
||||||
|
AS val_clause,
|
||||||
|
'_vals_' || Coalesce(geom_tablename || '_' || geom_geomref_colname, api_method) AS cte_name
|
||||||
|
FROM _meta
|
||||||
|
GROUP BY geom_tablename, geom_geomref_colname, geom_colname, api_method
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Generate clauses necessary to join together val_clauses
|
||||||
|
_val_joins AS (
|
||||||
|
SELECT String_Agg(a.cte_name || '.id = ' || b.cte_name || '.id ', ' AND ') val_joins
|
||||||
|
FROM _val_clauses a, _val_clauses b
|
||||||
|
WHERE a.cte_name != b.cte_name
|
||||||
|
AND a.cte_name < b.cte_name
|
||||||
|
),
|
||||||
|
|
||||||
|
-- Generate JSON clause. This puts together vals from val_clauses
|
||||||
|
_json_clause AS (SELECT
|
||||||
|
'SELECT ' || cdb_observatory.FIRST(cte_name) || '.id::INT,
|
||||||
|
Array_to_JSON(ARRAY[' || (SELECT String_Agg('val_' || colid, ', ') FROM _meta) || '])
|
||||||
|
FROM ' || String_Agg(cte_name, ', ') ||
|
||||||
|
Coalesce(' WHERE ' || val_joins, '')
|
||||||
|
AS json_clause
|
||||||
|
FROM _val_clauses, _val_joins
|
||||||
|
GROUP BY val_joins
|
||||||
|
)
|
||||||
|
|
||||||
|
SELECT (SELECT String_Agg(procgeom_clause, E',\n ') FROM _procgeom_clauses),
|
||||||
|
(SELECT String_Agg(val_clause, E',\n ') FROM _val_clauses),
|
||||||
|
json_clause
|
||||||
|
FROM _json_clause
|
||||||
|
$query$ INTO
|
||||||
|
procgeom_clauses,
|
||||||
|
val_clauses,
|
||||||
|
json_clause
|
||||||
|
USING params, geomtype, merge;
|
||||||
|
|
||||||
|
/* Execute query */
|
||||||
RETURN QUERY EXECUTE format($query$
|
RETURN QUERY EXECUTE format($query$
|
||||||
WITH _raw_geoms AS (%s),
|
WITH _raw_geoms AS (%s),
|
||||||
_geoms AS (SELECT id,
|
_geoms AS (SELECT id,
|
||||||
@ -827,27 +817,21 @@ BEGIN
|
|||||||
THEN ST_CollectionExtract(ST_MakeValid(ST_SimplifyVW(geom, 0.00001)), 3)
|
THEN ST_CollectionExtract(ST_MakeValid(ST_SimplifyVW(geom, 0.00001)), 3)
|
||||||
ELSE geom END geom
|
ELSE geom END geom
|
||||||
FROM _raw_geoms),
|
FROM _raw_geoms),
|
||||||
_procgeoms AS (SELECT _geoms.id, _geoms.geom %s %s
|
-- procgeom_clauses
|
||||||
FROM _geoms %s
|
%s,
|
||||||
%s
|
|
||||||
)
|
-- val_clauses
|
||||||
SELECT _procgeoms.id::INT, Array_to_JSON(ARRAY[%s]::JSON[])
|
%s
|
||||||
FROM _procgeoms %s
|
|
||||||
%s
|
-- json_clause
|
||||||
GROUP BY _procgeoms.id %s
|
%s
|
||||||
ORDER BY _procgeoms.id
|
$query$, CASE WHEN ARRAY_LENGTH(geomvals, 1) = 1
|
||||||
$query$, CASE WHEN ARRAY_LENGTH(geomvals, 1) = 1 THEN
|
THEN ' SELECT $1[1].val as id, $1[1].geom as geom '
|
||||||
' SELECT $1[1].val as id, $1[1].geom as geom '
|
ELSE ' SELECT val as id, geom FROM UNNEST($1) '
|
||||||
ELSE
|
|
||||||
' SELECT val as id, geom FROM UNNEST($1) '
|
|
||||||
END,
|
END,
|
||||||
', ' || NullIf(geomrefs_alias, ''),
|
String_Agg(procgeom_clauses, E',\n '),
|
||||||
', ' || NullIf(geom_colspecs, ''),
|
String_Agg(val_clauses, E',\n '),
|
||||||
', ' || NullIf(geom_tables, ''),
|
json_clause)
|
||||||
'WHERE ' || NullIf( user_wheres, ''),
|
|
||||||
data_colspecs, ', ' || NullIf(data_tables, ''),
|
|
||||||
'WHERE ' || NULLIF(obs_wheres, ''),
|
|
||||||
CASE WHEN merge IS False THEN ', ' || geomrefs_noalias ELSE '' END)
|
|
||||||
USING geomvals;
|
USING geomvals;
|
||||||
RETURN;
|
RETURN;
|
||||||
END;
|
END;
|
||||||
|
@ -153,6 +153,9 @@ t
|
|||||||
obs_getmeta_suggested_name
|
obs_getmeta_suggested_name
|
||||||
t
|
t
|
||||||
(1 row)
|
(1 row)
|
||||||
|
obs_getmeta_suggested_name_implicit_area
|
||||||
|
t
|
||||||
|
(1 row)
|
||||||
obs_getmeta_suggested_name_area
|
obs_getmeta_suggested_name_area
|
||||||
t
|
t
|
||||||
(1 row)
|
(1 row)
|
||||||
|
@ -268,7 +268,7 @@ SELECT
|
|||||||
(meta->0->>'numer_name') = 'Total Population' numer_name,
|
(meta->0->>'numer_name') = 'Total Population' numer_name,
|
||||||
(meta->0->>'denom_id') IS NULL denom_id,
|
(meta->0->>'denom_id') IS NULL denom_id,
|
||||||
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
||||||
(meta->0->>'normalization') IS NULL normalization
|
(meta->0->>'normalization') = 'area' normalization
|
||||||
FROM meta;
|
FROM meta;
|
||||||
|
|
||||||
-- OBS_GetMeta for point completes one partial measure with "best" metadata
|
-- OBS_GetMeta for point completes one partial measure with "best" metadata
|
||||||
@ -290,7 +290,7 @@ SELECT
|
|||||||
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
||||||
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
||||||
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
||||||
(meta->0->>'normalization') IS NULL normalization
|
(meta->0->>'normalization') = 'denominated' normalization
|
||||||
FROM meta;
|
FROM meta;
|
||||||
|
|
||||||
-- OBS_GetMeta for polygon completes one partial measure with "best" metadata
|
-- OBS_GetMeta for polygon completes one partial measure with "best" metadata
|
||||||
@ -308,7 +308,7 @@ SELECT
|
|||||||
(meta->0->>'numer_name') = 'Total Population' numer_name,
|
(meta->0->>'numer_name') = 'Total Population' numer_name,
|
||||||
(meta->0->>'denom_id') IS NULL denom_id,
|
(meta->0->>'denom_id') IS NULL denom_id,
|
||||||
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
||||||
(meta->0->>'normalization') IS NULL normalization
|
(meta->0->>'normalization') = 'area' normalization
|
||||||
FROM meta;
|
FROM meta;
|
||||||
|
|
||||||
-- OBS_GetMeta for polygon completes one partial measure with "best" metadata
|
-- OBS_GetMeta for polygon completes one partial measure with "best" metadata
|
||||||
@ -330,7 +330,7 @@ SELECT
|
|||||||
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
||||||
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
||||||
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
||||||
(meta->0->>'normalization') IS NULL normalization
|
(meta->0->>'normalization') = 'denominated' normalization
|
||||||
FROM meta;
|
FROM meta;
|
||||||
|
|
||||||
-- OBS_GetMeta for point completes several partial measures with "best"
|
-- OBS_GetMeta for point completes several partial measures with "best"
|
||||||
@ -352,7 +352,7 @@ SELECT
|
|||||||
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
||||||
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
||||||
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
(meta->0->>'geom_id') = 'us.census.tiger.block_group' geom_id,
|
||||||
(meta->0->>'normalization') IS NULL normalization,
|
(meta->0->>'normalization') = 'denominated' normalization,
|
||||||
(meta->1->>'id')::integer = 1 id,
|
(meta->1->>'id')::integer = 1 id,
|
||||||
(meta->1->>'numer_id') = 'us.census.acs.B01001002' numer_id,
|
(meta->1->>'numer_id') = 'us.census.acs.B01001002' numer_id,
|
||||||
(meta->1->>'timespan_rank')::integer = 1 timespan_rank,
|
(meta->1->>'timespan_rank')::integer = 1 timespan_rank,
|
||||||
@ -367,7 +367,7 @@ SELECT
|
|||||||
(meta->1->>'denom_type') = 'Numeric' denom_type,
|
(meta->1->>'denom_type') = 'Numeric' denom_type,
|
||||||
(meta->1->>'denom_name') = 'Total Population' denom_name,
|
(meta->1->>'denom_name') = 'Total Population' denom_name,
|
||||||
(meta->1->>'geom_id') = 'us.census.tiger.census_tract' geom_id,
|
(meta->1->>'geom_id') = 'us.census.tiger.census_tract' geom_id,
|
||||||
(meta->1->>'normalization') IS NULL normalization
|
(meta->1->>'normalization') = 'denominated' normalization
|
||||||
FROM meta;
|
FROM meta;
|
||||||
|
|
||||||
-- OBS_GetMeta for point completes several partial measures with "best" metadata
|
-- OBS_GetMeta for point completes several partial measures with "best" metadata
|
||||||
@ -389,7 +389,7 @@ SELECT
|
|||||||
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
(meta->0->>'denom_type') = 'Numeric' denom_type,
|
||||||
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
(meta->0->>'denom_name') = 'Total Population' denom_name,
|
||||||
(meta->0->>'geom_id') = 'us.census.tiger.census_tract' geom_id,
|
(meta->0->>'geom_id') = 'us.census.tiger.census_tract' geom_id,
|
||||||
(meta->0->>'normalization') IS NULL normalization
|
(meta->0->>'normalization') = 'denominated' normalization
|
||||||
FROM meta;
|
FROM meta;
|
||||||
|
|
||||||
-- OBS_GetMeta for point completes several partial measures with conflicting
|
-- OBS_GetMeta for point completes several partial measures with conflicting
|
||||||
@ -400,9 +400,14 @@ AS obs_getmeta_conflicting_metadata;
|
|||||||
|
|
||||||
-- OBS_GetMeta provides suggested name for simple meta request
|
-- OBS_GetMeta provides suggested name for simple meta request
|
||||||
SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestPoint(),
|
SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestPoint(),
|
||||||
'[{"numer_id": "us.census.acs.B01003001"}]'
|
'[{"numer_id": "us.census.acs.B01003001", "normalization": "predenom"}]'
|
||||||
)->0->>'suggested_name' = 'total_pop_2010_2014' obs_getmeta_suggested_name;
|
)->0->>'suggested_name' = 'total_pop_2010_2014' obs_getmeta_suggested_name;
|
||||||
|
|
||||||
|
-- OBS_GetMeta provides suggested name for simple meta request with area norm
|
||||||
|
SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestPoint(),
|
||||||
|
'[{"numer_id": "us.census.acs.B01003001"}]'
|
||||||
|
)->0->>'suggested_name' = 'total_pop_per_sq_km_2010_2014' obs_getmeta_suggested_name_implicit_area;
|
||||||
|
|
||||||
-- OBS_GetMeta provides suggested name for simple meta request with area norm
|
-- OBS_GetMeta provides suggested name for simple meta request with area norm
|
||||||
SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestPoint(),
|
SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestPoint(),
|
||||||
'[{"numer_id": "us.census.acs.B01003001", "normalization": "area"}]'
|
'[{"numer_id": "us.census.acs.B01003001", "normalization": "area"}]'
|
||||||
@ -677,25 +682,25 @@ FROM data;
|
|||||||
-- OBS_GetData/OBS_GetMeta by geom with polygons inside a polygon + one measure
|
-- OBS_GetData/OBS_GetMeta by geom with polygons inside a polygon + one measure
|
||||||
WITH
|
WITH
|
||||||
meta AS (SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestArea(),
|
meta AS (SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestArea(),
|
||||||
'[{"geom_id": "us.census.tiger.block_group"}, {"numer_id": "us.census.acs.B01003001", "geom_id": "us.census.tiger.block_group"}]') meta),
|
'[{"geom_id": "us.census.tiger.block_group"}, {"numer_id": "us.census.acs.B01003001", "normalization": "predenom", "geom_id": "us.census.tiger.block_group"}]') meta),
|
||||||
data AS (SELECT * FROM cdb_observatory.OBS_GetData(
|
data AS (SELECT * FROM cdb_observatory.OBS_GetData(
|
||||||
ARRAY[(cdb_observatory._TestArea(), 1)::geomval],
|
ARRAY[(cdb_observatory._TestArea(), 1)::geomval],
|
||||||
(SELECT meta FROM meta), false))
|
(SELECT meta FROM meta), false))
|
||||||
SELECT every(id = 1) is TRUE id,
|
SELECT every(id = 1) is TRUE id,
|
||||||
count(distinct (data->0->>'value')::geometry) = 16 correct_num_geoms,
|
count(distinct (data->0->>'value')::geometry) = 16 correct_num_geoms,
|
||||||
abs(sum((data->1->>'value')::numeric) - 15787) / 15787 < 0.001 correct_pop
|
abs(sum((data->1->>'value')::numeric) - 12327) / 12327 < 0.001 correct_pop
|
||||||
FROM data;
|
FROM data;
|
||||||
|
|
||||||
-- OBS_GetData/OBS_GetMeta by geom with polygons inside a polygon + one measure + one text
|
-- OBS_GetData/OBS_GetMeta by geom with polygons inside a polygon + one measure + one text
|
||||||
WITH
|
WITH
|
||||||
meta AS (SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestArea(),
|
meta AS (SELECT cdb_observatory.OBS_GetMeta(cdb_observatory._TestArea(),
|
||||||
'[{"geom_id": "us.census.tiger.block_group"}, {"numer_id": "us.census.acs.B01003001", "geom_id": "us.census.tiger.block_group"}, {"numer_id": "us.census.tiger.name", "geom_id": "us.census.tiger.block_group"}]') meta),
|
'[{"geom_id": "us.census.tiger.block_group"}, {"numer_id": "us.census.acs.B01003001", "normalization": "predenom", "geom_id": "us.census.tiger.block_group"}, {"numer_id": "us.census.tiger.name", "geom_id": "us.census.tiger.block_group"}]') meta),
|
||||||
data AS (SELECT * FROM cdb_observatory.OBS_GetData(
|
data AS (SELECT * FROM cdb_observatory.OBS_GetData(
|
||||||
ARRAY[(cdb_observatory._TestArea(), 1)::geomval],
|
ARRAY[(cdb_observatory._TestArea(), 1)::geomval],
|
||||||
(SELECT meta FROM meta), false))
|
(SELECT meta FROM meta), false))
|
||||||
SELECT every(id = 1) is TRUE id,
|
SELECT every(id = 1) is TRUE id,
|
||||||
count(distinct (data->0->>'value')::geometry) = 16 correct_num_geoms,
|
count(distinct (data->0->>'value')::geometry) = 16 correct_num_geoms,
|
||||||
abs(sum((data->1->>'value')::numeric) - 15787) / 15787 < 0.001 correct_pop,
|
abs(sum((data->1->>'value')::numeric) - 12327) / 12327 < 0.001 correct_pop,
|
||||||
array_agg(distinct data->2->>'value') = '{"Block Group 1","Block Group 2","Block Group 3","Block Group 4","Block Group 5"}' correct_bg_names
|
array_agg(distinct data->2->>'value') = '{"Block Group 1","Block Group 2","Block Group 3","Block Group 4","Block Group 5"}' correct_bg_names
|
||||||
FROM data;
|
FROM data;
|
||||||
|
|
||||||
|
Loading…
Reference in New Issue
Block a user