Merge branch 'nonsum-interpolation' into release-v-1.3.1

This commit is contained in:
John Krauss 2017-02-16 17:20:38 +00:00
commit 9bda063148
5 changed files with 668 additions and 482 deletions

View File

@ -205,6 +205,18 @@ END;
$$ LANGUAGE plpgsql;
-- Function we can call to raise an exception in the midst of a SQL statement
CREATE OR REPLACE FUNCTION cdb_observatory._OBS_RaiseNotice(
message TEXT
) RETURNS TEXT
AS $$
BEGIN
RAISE NOTICE '%', message;
RETURN NULL;
END;
$$ LANGUAGE plpgsql;
-- Create a function that always returns the first non-NULL item
CREATE OR REPLACE FUNCTION cdb_observatory.first_agg ( anyelement, anyelement )
RETURNS anyelement LANGUAGE SQL IMMUTABLE STRICT AS $$

View File

@ -174,6 +174,7 @@ BEGIN
CASE WHEN f.numer_id IS NULL THEN NULL ELSE denom_tablename END denom_tablename,
CASE WHEN f.numer_id IS NULL THEN NULL ELSE denom_name END denom_name,
CASE WHEN f.numer_id IS NULL THEN NULL ELSE denom_type END denom_type,
CASE WHEN f.numer_id IS NULL THEN NULL ELSE denom_reltype END denom_reltype,
m.geom_id,
m.geom_timespan,
geom_colname,
@ -212,16 +213,23 @@ BEGIN
'numer_geomref_colname', cdb_observatory.FIRST(meta.numer_geomref_colname),
'numer_tablename', cdb_observatory.FIRST(meta.numer_tablename),
'numer_type', cdb_observatory.FIRST(meta.numer_type),
--'numer_description', cdb_observatory.FIRST(meta.numer_description),
--'numer_t_description', cdb_observatory.FIRST(meta.numer_t_description),
'denom_aggregate', cdb_observatory.FIRST(meta.denom_aggregate),
'denom_colname', cdb_observatory.FIRST(denom_colname),
'denom_geomref_colname', cdb_observatory.FIRST(denom_geomref_colname),
'denom_tablename', cdb_observatory.FIRST(denom_tablename),
'denom_type', cdb_observatory.FIRST(meta.denom_type),
'denom_reltype', cdb_observatory.FIRST(meta.denom_reltype),
--'denom_description', cdb_observatory.FIRST(meta.denom_description),
--'denom_t_description', cdb_observatory.FIRST(meta.denom_t_description),
'geom_colname', cdb_observatory.FIRST(geom_colname),
'geom_geomref_colname', cdb_observatory.FIRST(geom_geomref_colname),
'geom_tablename', cdb_observatory.FIRST(geom_tablename),
'geom_type', cdb_observatory.FIRST(meta.geom_type),
'geom_timespan', cdb_observatory.FIRST(meta.geom_timespan),
--'geom_description', cdb_observatory.FIRST(meta.geom_description),
--'geom_t_description', cdb_observatory.FIRST(meta.geom_t_description),
'numer_timespan', cdb_observatory.FIRST(numer_timespan),
'numer_name', cdb_observatory.FIRST(numer_name),
'denom_name', cdb_observatory.FIRST(denom_name),
@ -409,6 +417,7 @@ BEGIN
(unnest($1))->>'denom_geomref_colname' denom_geomref_colname,
(unnest($1))->>'denom_tablename' denom_tablename,
(unnest($1))->>'denom_type' denom_type,
(unnest($1))->>'denom_reltype' denom_reltype,
(unnest($1))->>'geom_id' geom_id,
(unnest($1))->>'geom_colname' geom_colname,
(unnest($1))->>'geom_geomref_colname' geom_geomref_colname,
@ -546,6 +555,7 @@ BEGIN
(unnest($1))->>'denom_geomref_colname' denom_geomref_colname,
(unnest($1))->>'denom_tablename' denom_tablename,
(unnest($1))->>'denom_type' denom_type,
(unnest($1))->>'denom_reltype' denom_reltype,
(unnest($1))->>'geom_id' geom_id,
(unnest($1))->>'geom_colname' geom_colname,
(unnest($1))->>'geom_geomref_colname' geom_geomref_colname,
@ -568,7 +578,8 @@ BEGIN
WHEN LOWER(numer_type) LIKE 'numeric' THEN
'''value'', ' || CASE
-- denominated
WHEN LOWER(normalization) LIKE 'denom%' OR (normalization IS NULL AND denom_id IS NOT NULL)
WHEN LOWER(normalization) LIKE 'denom%' OR
(normalization IS NULL AND LOWER(denom_reltype) LIKE 'denominator')
THEN ' CASE ' ||
-- denominated point-in-poly or user polygon is same as OBS polygon
' WHEN ST_GeometryType(cdb_observatory.FIRST(_geoms.geom)) = ''ST_Point'' ' ||
@ -597,7 +608,8 @@ BEGIN
' / (COUNT(*) / COUNT(distinct ' || geom_tablename || '.' || geom_geomref_colname || ')) ' ||
' END '
-- areaNormalized
WHEN LOWER(normalization) LIKE 'area%' OR (normalization IS NULL AND numer_aggregate ILIKE 'sum')
WHEN LOWER(normalization) LIKE 'area%' OR
(normalization IS NULL AND numer_aggregate ILIKE 'sum')
THEN ' CASE ' ||
-- areaNormalized point-in-poly or user polygon is the same as OBS polygon
' WHEN ST_GeometryType(cdb_observatory.FIRST(_geoms.geom)) = ''ST_Point'' ' ||
@ -618,15 +630,49 @@ BEGIN
' END / (ST_Area(' || geom_tablename || '.' || geom_colname || '::Geography) / 1000000)) ' ||
' / (COUNT(*) / COUNT(distinct ' || geom_tablename || '.' || geom_geomref_colname || ')) ' ||
' END '
-- prenormalized
ELSE ' CASE ' ||
-- 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 'predenominated')
THEN ' CASE ' ||
-- predenominated point-in-poly or user polygon is the same as OBS- polygon
' WHEN ST_GeometryType(cdb_observatory.FIRST(_geoms.geom)) = ''ST_Point'' ' ||
' OR cdb_observatory.FIRST(_geoms.geom = ' || geom_tablename || '.' || geom_colname || ')' ||
' 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 ||
' * CASE WHEN ST_Within(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ') ' ||
' THEN ST_Area(_geoms.geom) / ST_Area(' || geom_tablename || '.' || geom_colname || ') ' ||
' WHEN ST_Within(' || geom_tablename || '.' || geom_colname || ', _geoms.geom) ' ||
' THEN 1 ' ||
' ELSE (ST_Area(ST_Intersection(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ')) ' ||
' / ST_Area(' || geom_tablename || '.' || geom_colname || '))' ||
' END) ' ||
' / SUM(' || denom_tablename || '.' || denom_colname ||
' * CASE WHEN ST_Within(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ') ' ||
' THEN ST_Area(_geoms.geom) / ST_Area(' || geom_tablename || '.' || geom_colname || ') ' ||
' WHEN ST_Within(' || geom_tablename || '.' || geom_colname || ', _geoms.geom) ' ||
' THEN 1 ' ||
' ELSE (ST_Area(ST_Intersection(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ')) ' ||
' / ST_Area(' || geom_tablename || '.' || geom_colname || '))' ||
' END) ' ||
' / (COUNT(*) / COUNT(distinct ' || geom_tablename || '.' || geom_geomref_colname || ')) ' ||
'END '
-- prenormalized for summable measures. point or summable only!
WHEN numer_aggregate ILIKE 'sum' AND
(normalization IS NULL OR LOWER(normalization) LIKE 'predenom%')
THEN ' CASE ' ||
-- predenominated point-in-poly or user polygon is the same as OBS- polygon
' WHEN ST_GeometryType(cdb_observatory.FIRST(_geoms.geom)) = ''ST_Point'' ' ||
' OR cdb_observatory.FIRST(_geoms.geom = ' || geom_tablename || '.' || geom_colname || ')' ||
' THEN cdb_observatory.FIRST(' || numer_tablename || '.' || numer_colname || ') ' ||
' ELSE ' ||
-- predenominated polygon interpolation
-- TODO should weight by universe instead of area
-- SUM (numer * (% user geom in OBS geom))
' SUM(' || numer_tablename || '.' || numer_colname || ' ' ||
' * CASE WHEN ST_Within(_geoms.geom, ' || geom_tablename || '.' || geom_colname || ') ' ||
@ -638,6 +684,14 @@ BEGIN
' END) ' ||
' / (COUNT(*) / COUNT(distinct ' || geom_tablename || '.' || geom_geomref_colname || ')) ' ||
'END '
-- Everything else. Point only!
ELSE ' CASE ' ||
' WHEN ST_GeometryType(cdb_observatory.FIRST(_geoms.geom)) = ''ST_Point'' ' ||
' OR cdb_observatory.FIRST(_geoms.geom = ' || geom_tablename || '.' || geom_colname || ')' ||
' 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

View File

@ -48,6 +48,15 @@ t
obs_getmeasure_out_of_bounds_geometry
t
(1 row)
obs_getmeasure_estimate_for_blank_aggregate
t
(1 row)
obs_getmeasure_per_capita_income_average
t
(1 row)
obs_getmeasure_median_capita_income_average
t
(1 row)
obs_getcategory_point
t
(1 row)

File diff suppressed because one or more lines are too long

View File

@ -106,6 +106,21 @@ SELECT cdb_observatory.OBS_GetMeasure(
ST_SetSRID(st_point(0, 0), 4326),
'us.census.acs.B01003001') IS NULL As OBS_GetMeasure_out_of_bounds_geometry;
-- OBS_GetMeasure over arbitrary area for a measure we cannot estimate
SELECT cdb_observatory.OBS_GetMeasure(
ST_Buffer(cdb_observatory._testpoint(), 0.1),
'us.census.acs.B19083001') IS NULL As OBS_GetMeasure_estimate_for_blank_aggregate;
-- OBS_GetMeasure over arbitrary area for an average measure we can estimate
SELECT abs(cdb_observatory.OBS_GetMeasure(
ST_Buffer(cdb_observatory._testpoint(), 0.01),
'us.census.acs.B19301001') - 20025) / 20025 < 0.001 As OBS_GetMeasure_per_capita_income_average;
-- OBS_GetMeasure over arbitrary area for a median measure we can estimate
SELECT abs(cdb_observatory.OBS_GetMeasure(
ST_Buffer(cdb_observatory._testpoint(), 0.01),
'us.census.acs.B19013001') - 39266) / 39266 < 0.001 As OBS_GetMeasure_median_capita_income_average;
-- Point-based OBS_GetCategory
SELECT cdb_observatory.OBS_GetCategory(
cdb_observatory._TestPoint(), 'us.census.spielman_singleton_segments.X10') = 'Wealthy, urban without Kids' As OBS_GetCategory_point;