Merge pull request #300 from CartoDB/4967_new_numerators_function
New private function _OBS_GetNumerators to be used in our UI
This commit is contained in:
commit
aedc45f2a8
@ -181,6 +181,86 @@ BEGIN
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory._OBS_GetNumerators(
|
||||
bounds GEOMETRY DEFAULT NULL,
|
||||
section_tags TEXT[] DEFAULT ARRAY[]::TEXT[],
|
||||
subsection_tags TEXT[] DEFAULT ARRAY[]::TEXT[],
|
||||
other_tags TEXT[] DEFAULT ARRAY[]::TEXT[],
|
||||
ids TEXT[] DEFAULT ARRAY[]::TEXT[],
|
||||
name TEXT DEFAULT NULL,
|
||||
denom_id TEXT DEFAULT '',
|
||||
geom_id TEXT DEFAULT '',
|
||||
timespan TEXT DEFAULT ''
|
||||
) RETURNS TABLE (
|
||||
numer_id TEXT,
|
||||
numer_name TEXT,
|
||||
numer_description TEXT,
|
||||
numer_weight NUMERIC,
|
||||
numer_license TEXT,
|
||||
numer_source TEXT,
|
||||
numer_type TEXT,
|
||||
numer_aggregate TEXT,
|
||||
numer_extra JSONB,
|
||||
numer_tags JSONB,
|
||||
valid_denom BOOLEAN,
|
||||
valid_geom BOOLEAN,
|
||||
valid_timespan BOOLEAN
|
||||
) AS $$
|
||||
DECLARE
|
||||
where_clause_elements TEXT[];
|
||||
geom_clause TEXT;
|
||||
where_clause TEXT;
|
||||
BEGIN
|
||||
where_clause_elements := (ARRAY[])::TEXT[];
|
||||
where_clause := '';
|
||||
|
||||
IF bounds IS NOT NULL THEN
|
||||
where_clause_elements := array_append(where_clause_elements, format($data$ST_Intersects(the_geom, '%s'::geometry)$data$, bounds));
|
||||
END IF;
|
||||
IF cardinality(section_tags) > 0 THEN
|
||||
where_clause_elements := array_append(where_clause_elements, format($data$numer_tags ?| '%s'$data$, section_tags));
|
||||
END IF;
|
||||
IF cardinality(subsection_tags) > 0 THEN
|
||||
where_clause_elements := array_append(where_clause_elements, format($data$numer_tags ?| '%s'$data$, subsection_tags));
|
||||
END IF;
|
||||
IF cardinality(other_tags) > 0 THEN
|
||||
where_clause_elements := array_append(where_clause_elements, format($data$numer_tags ?| '%s'$data$, other_tags));
|
||||
END IF;
|
||||
IF cardinality(ids) > 0 THEN
|
||||
where_clause_elements := array_append(where_clause_elements, format($data$numer_id IN (array_to_string('%s'::text[], ','))$data$, ids));
|
||||
END IF;
|
||||
IF name IS NOT NULL AND name != '' THEN
|
||||
where_clause_elements := array_append(where_clause_elements, format($data$numer_name ilike '%%%s%%'$data$, name));
|
||||
END IF;
|
||||
IF cardinality(where_clause_elements) > 0 THEN
|
||||
where_clause := format($clause$WHERE %s$clause$, array_to_string(where_clause_elements, ' AND '));
|
||||
END IF;
|
||||
RAISE DEBUG '%', array_to_string(where_clause_elements, ' AND ');
|
||||
|
||||
RETURN QUERY
|
||||
EXECUTE
|
||||
format($string$
|
||||
SELECT numer_id::TEXT,
|
||||
numer_name::TEXT,
|
||||
numer_description::TEXT,
|
||||
numer_weight::NUMERIC,
|
||||
NULL::TEXT license,
|
||||
NULL::TEXT source,
|
||||
numer_type numer_type,
|
||||
numer_aggregate numer_aggregate,
|
||||
numer_extra::JSONB numer_extra,
|
||||
numer_tags numer_tags,
|
||||
$1 = ANY(denoms) valid_denom,
|
||||
$2 = ANY(geoms) valid_geom,
|
||||
$3 = ANY(timespans) valid_timespan
|
||||
FROM observatory.obs_meta_numer
|
||||
%s
|
||||
$string$, where_clause)
|
||||
USING denom_id, geom_id, timespan;
|
||||
RETURN;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetAvailableDenominators(
|
||||
bounds GEOMETRY DEFAULT NULL,
|
||||
filter_tags TEXT[] DEFAULT NULL,
|
||||
|
@ -48,6 +48,63 @@ t
|
||||
_obs_getavailablenumerators_no_total_pop_1996
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_usa_pop_in_all
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_usa_pop_in_nyc_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_usa_pop_in_usa_extents
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_no_usa_pop_not_in_zero_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_usa_pop_in_age_gender_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_no_pop_in_income_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_male_pop_denom_by_total_pop
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_no_income_denom_by_total_pop
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_zillow_at_zcta5
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_no_zillow_at_block_group
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_2010_2014
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_no_total_pop_1996
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_by_name
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_by_section
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_not_in_canada
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_by_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_not_in_employment_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_by_id
|
||||
t
|
||||
(1 row)
|
||||
_obs_getnumerators_total_pop_not_with_other_id
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_usa_pop_in_all
|
||||
t
|
||||
(1 row)
|
||||
|
@ -119,6 +119,142 @@ FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getavailablenumerators_no_total_pop_1996;
|
||||
|
||||
--
|
||||
-- _OBS_GetNumerators tests
|
||||
--
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators())
|
||||
AS _obs_getnumerators_usa_pop_in_all;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getnumerators_usa_pop_in_nyc_point;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakeEnvelope(
|
||||
-169.8046875, 21.289374355860424,
|
||||
-47.4609375, 72.0739114882038
|
||||
), 4326),
|
||||
NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getnumerators_usa_pop_in_usa_extents;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(0, 0), 4326),
|
||||
NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getnumerators_no_usa_pop_not_in_zero_point;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
subsection_tags => ARRAY['subsection/tags.age_gender']
|
||||
))
|
||||
AS _obs_getnumerators_usa_pop_in_age_gender_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
subsection_tags => ARRAY['subsection/tags.income']
|
||||
))
|
||||
AS _obs_getnumerators_no_pop_in_income_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01001002' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
denom_id => 'us.census.acs.B01003001'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getnumerators_male_pop_denom_by_total_pop;
|
||||
|
||||
SELECT 'us.census.acs.B19013001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
denom_id => 'us.census.acs.B01003001'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getnumerators_no_income_denom_by_total_pop;
|
||||
|
||||
SELECT 'us.zillow.AllHomes_Zhvi' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
geom_id => 'us.census.tiger.zcta5'
|
||||
) WHERE valid_geom = True)
|
||||
AS _obs_getnumerators_zillow_at_zcta5;
|
||||
|
||||
SELECT 'us.zillow.AllHomes_Zhvi' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
geom_id => 'us.census.tiger.block_group'
|
||||
) WHERE valid_geom = True)
|
||||
AS _obs_getnumerators_no_zillow_at_block_group;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
timespan => '2010 - 2014'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getnumerators_total_pop_2010_2014;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
timespan => '1996'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getnumerators_no_total_pop_1996;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
name => 'tot'
|
||||
))
|
||||
AS _obs_getnumerators_total_pop_by_name;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
section_tags => '{section/tags.united_states}'
|
||||
))
|
||||
AS _obs_getnumerators_total_pop_by_section;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
section_tags => '{section/tags.ca}'
|
||||
))
|
||||
AS _obs_getnumerators_total_pop_not_in_canada;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
section_tags => '{section/tags.united_states}',
|
||||
subsection_tags => '{subsection/tags.age_gender}'
|
||||
))
|
||||
AS _obs_getnumerators_total_pop_by_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
section_tags => '{section/tags.united_states}',
|
||||
subsection_tags => '{subsection/tags.employment}'
|
||||
))
|
||||
AS _obs_getnumerators_total_pop_not_in_employment_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ids => '{us.census.acs.B01003001}'
|
||||
))
|
||||
AS _obs_getnumerators_total_pop_by_id;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory._OBS_GetNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ids => '{us.census.acs.B01003002}'
|
||||
))
|
||||
AS _obs_getnumerators_total_pop_not_with_other_id;
|
||||
|
||||
--
|
||||
-- OBS_GetAvailableDenominators tests
|
||||
--
|
||||
|
Loading…
Reference in New Issue
Block a user