commit
efae735324
22
NEWS.md
22
NEWS.md
@ -1,3 +1,25 @@
|
||||
1.1.0 (2016-10-04)
|
||||
|
||||
__Bugfixes__
|
||||
|
||||
* Fixed some minor errors in test suite
|
||||
|
||||
__Improvements__
|
||||
|
||||
* We now generate test fixtures from local data instead of remote server
|
||||
([#120](https://github.com/CartoDB/observatory-extension/issues/120))
|
||||
|
||||
__API Changes__
|
||||
|
||||
* New function, `OBS_LegacyBuilderMetadata`, which resolves
|
||||
([#133]( https://github.com/CartoDB/observatory-extension/issues/133))
|
||||
* Creates "dimensional" metadata grabbing functions
|
||||
(`OBS_GetAvailableNumerators`, `OBS_GetAvailableDenominators`,
|
||||
`OBS_GetAvailableGeometries`, `OBS_GetAvailableTimespans`) which will be
|
||||
used for obtaining metadata in the replacement for the Data Library
|
||||
([CartoDB/design#104](https://github.com/CartoDB/design/issues/104)). This
|
||||
is also referred to here ([CartoDB/design#68](https://github.com/CartoDB/design/issues/68)).
|
||||
|
||||
1.0.7 (2016-09-20)
|
||||
|
||||
__Bugfixes__
|
||||
|
@ -1,213 +1,331 @@
|
||||
import os
|
||||
import psycopg2
|
||||
import subprocess
|
||||
|
||||
DB_CONN = psycopg2.connect('postgres://{user}:{password}@{host}:{port}/{database}'.format(
|
||||
user=os.environ.get('PGUSER', 'postgres'),
|
||||
password=os.environ.get('PGPASSWORD', ''),
|
||||
host=os.environ.get('PGHOST', 'localhost'),
|
||||
port=os.environ.get('PGPORT', '5432'),
|
||||
database=os.environ.get('PGDATABASE', 'postgres'),
|
||||
))
|
||||
CURSOR = DB_CONN.cursor()
|
||||
|
||||
|
||||
def query(q):
|
||||
'''
|
||||
Query the database.
|
||||
'''
|
||||
try:
|
||||
CURSOR.execute(q)
|
||||
return CURSOR
|
||||
except:
|
||||
DB_CONN.rollback()
|
||||
raise
|
||||
|
||||
|
||||
def commit():
|
||||
try:
|
||||
DB_CONN.commit()
|
||||
except:
|
||||
DB_CONN.rollback()
|
||||
raise
|
||||
|
||||
from sqldumpr import Dumpr
|
||||
|
||||
def get_tablename_query(column_id, boundary_id, timespan):
|
||||
"""
|
||||
given a column_id, boundary-id (us.census.tiger.block_group), and
|
||||
timespan, give back the current table hash from the data observatory
|
||||
"""
|
||||
q = """
|
||||
SELECT t.tablename, geoid_ct.colname colname
|
||||
FROM obs_table t,
|
||||
obs_column_table geoid_ct,
|
||||
obs_column_table data_ct
|
||||
return """
|
||||
SELECT t.tablename, geoid_ct.colname colname, t.id table_id
|
||||
FROM observatory.obs_table t,
|
||||
observatory.obs_column_table geoid_ct,
|
||||
observatory.obs_column_table data_ct
|
||||
WHERE
|
||||
t.id = geoid_ct.table_id AND
|
||||
t.id = data_ct.table_id AND
|
||||
geoid_ct.column_id =
|
||||
(SELECT source_id
|
||||
FROM obs_column_to_column
|
||||
FROM observatory.obs_column_to_column
|
||||
WHERE target_id = '{boundary_id}'
|
||||
AND reltype = 'geom_ref'
|
||||
) AND
|
||||
data_ct.column_id = '{column_id}' AND
|
||||
timespan = '{timespan}'
|
||||
""".replace('\n','')
|
||||
""".format(column_id=column_id,
|
||||
boundary_id=boundary_id,
|
||||
timespan=timespan)
|
||||
|
||||
return q.format(column_id=column_id,
|
||||
boundary_id=boundary_id,
|
||||
timespan=timespan)
|
||||
|
||||
def select_star(tablename):
|
||||
return "SELECT * FROM {}".format(tablename)
|
||||
METADATA_TABLES = ['obs_table', 'obs_column_table', 'obs_column', 'obs_column_tag',
|
||||
'obs_tag', 'obs_column_to_column', 'obs_dump_version', 'obs_meta',
|
||||
'obs_meta_numer', 'obs_meta_denom', 'obs_meta_geom',
|
||||
'obs_meta_timespan', ]
|
||||
|
||||
cdb = Dumpr('observatory.cartodb.com','')
|
||||
|
||||
metadata = ['obs_table', 'obs_column_table', 'obs_column', 'obs_column_tag',
|
||||
'obs_tag', 'obs_column_to_column', 'obs_dump_version', ]
|
||||
|
||||
fixtures = [
|
||||
FIXTURES = [
|
||||
('us.census.acs.B01003001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B01001002_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B01001026_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B01002001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B03002003_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B03002004_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B03002006_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B03002012_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B05001006_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B08006001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B08006002_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B08006008_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B08006009_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B08006011_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B08006015_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B08006017_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B09001001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B11001001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B14001001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B14001002_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B14001005_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B14001006_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B14001007_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B14001008_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B15003001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B15003017_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B15003022_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B15003023_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B16001001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B16001002_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B16001003_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B17001001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B17001002_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B19013001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B19083001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B19301001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25001001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25002003_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25004002_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25004004_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25058001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25071001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25075001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B25075025_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B01003001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B01001002', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B01001026', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B01002001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002003', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002004', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002006', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002012', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002005', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002008', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002009', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B03002002', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B11001001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B15003001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B15003017', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B15003019', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B15003020', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B15003021', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B15003022', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B15003023', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19013001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19083001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19301001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25001001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25002003', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25004002', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25004004', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25058001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25071001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25075001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25075025', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B25081002', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134002', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134003', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134004', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134005', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134006', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134007', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134008', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134009', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08134010', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B08135001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001002', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001003', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001004', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001005', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001006', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001007', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001008', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001009', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001010', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001011', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001012', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001013', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001014', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001015', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001016', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B19001017', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.tiger.census_tract', 'us.census.tiger.census_tract', '2014'),
|
||||
('us.census.tiger.block_group', 'us.census.tiger.block_group', '2014'),
|
||||
('us.census.tiger.zcta5', 'us.census.tiger.zcta5', '2014'),
|
||||
('us.census.tiger.county', 'us.census.tiger.county', '2014'),
|
||||
('us.census.acs.B01001002', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.acs.B01003001', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B01003001_quantile', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.acs.B01003001', 'us.census.tiger.block_group', '2010 - 2014'),
|
||||
('us.census.spielman_singleton_segments.X2', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.spielman_singleton_segments.X10', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.spielman_singleton_segments.X31', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.census.spielman_singleton_segments.X55', 'us.census.tiger.census_tract', '2010 - 2014'),
|
||||
('us.zillow.AllHomes_Zhvi', 'us.census.tiger.zcta5', '2014-01'),
|
||||
('us.zillow.AllHomes_Zhvi', 'us.census.tiger.zcta5', '2016-03'),
|
||||
('us.zillow.AllHomes_Zhvi', 'us.census.tiger.zcta5', '2016-06'),
|
||||
('whosonfirst.wof_country_geom', 'whosonfirst.wof_country_geom', '2016'),
|
||||
('us.census.tiger.zcta5_clipped', 'us.census.tiger.zcta5_clipped', '2014'),
|
||||
('us.census.tiger.block_group_clipped', 'us.census.tiger.block_group_clipped', '2014'),
|
||||
('us.census.tiger.census_tract_clipped', 'us.census.tiger.census_tract_clipped', '2014'),
|
||||
]
|
||||
|
||||
unique_tables = set()
|
||||
OUTFILE_PATH = os.path.join(os.path.dirname(__file__), '..',
|
||||
'src/pg/test/fixtures/load_fixtures.sql')
|
||||
DROPFILE_PATH = os.path.join(os.path.dirname(__file__), '..',
|
||||
'src/pg/test/fixtures/drop_fixtures.sql')
|
||||
|
||||
for f in fixtures:
|
||||
column_id, boundary_id, timespan = f
|
||||
tablename_query = get_tablename_query(*f)
|
||||
resp = cdb.query(tablename_query).json()['rows'][0]
|
||||
tablename = resp['tablename']
|
||||
colname = resp['colname']
|
||||
table_colname = (tablename, colname, boundary_id, )
|
||||
if table_colname not in unique_tables:
|
||||
print table_colname
|
||||
unique_tables.add(table_colname)
|
||||
def dump(cols, tablename, where=''):
|
||||
|
||||
print unique_tables
|
||||
with open(DROPFILE_PATH, 'a') as dropfile:
|
||||
dropfile.write('DROP TABLE IF EXISTS observatory.{tablename};\n'.format(
|
||||
tablename=tablename,
|
||||
))
|
||||
|
||||
with open('src/pg/test/fixtures/load_fixtures.sql', 'w') as outfile:
|
||||
with open('src/pg/test/fixtures/drop_fixtures.sql', 'w') as dropfiles:
|
||||
outfile.write('SET client_min_messages TO WARNING;\n\set ECHO none\n')
|
||||
dropfiles.write('SET client_min_messages TO WARNING;\n\set ECHO none\n')
|
||||
for tablename in metadata:
|
||||
cdb.dump(select_star(tablename), tablename, outfile, schema='observatory')
|
||||
dropfiles.write('DROP TABLE IF EXISTS observatory.{};\n'.format(tablename))
|
||||
print tablename
|
||||
subprocess.check_call('pg_dump -x --section=pre-data -t observatory.{tablename} '
|
||||
' | sed "s:SET search_path.*::" '
|
||||
' | sed "s:CREATE TABLE :CREATE TABLE observatory.:" '
|
||||
' | sed "s:ALTER TABLE.*OWNER.*::" '
|
||||
' >> {outfile}'.format(
|
||||
tablename=tablename,
|
||||
outfile=OUTFILE_PATH,
|
||||
), shell=True)
|
||||
|
||||
for tablename, colname, boundary_id in unique_tables:
|
||||
if 'zcta5' in boundary_id:
|
||||
where = '\'11%\''
|
||||
compare = 'LIKE'
|
||||
elif 'whosonfirst' in boundary_id:
|
||||
where = '(\'85632785\',\'85633051\',\'85633111\',\'85633147\',\'85633253\',\'85633267\')'
|
||||
compare = 'IN'
|
||||
else:
|
||||
where = '\'36047%\''
|
||||
compare = 'LIKE'
|
||||
print ' '.join([select_star(tablename), "WHERE {}::text {} {}".format(colname, compare, where)])
|
||||
cdb.dump(' '.join([select_star(tablename), "WHERE {}::text {} {}".format(colname, compare, where)]),
|
||||
tablename, outfile, schema='observatory')
|
||||
dropfiles.write('DROP TABLE IF EXISTS observatory.{};\n'.format(tablename))
|
||||
with open(OUTFILE_PATH, 'a') as outfile:
|
||||
outfile.write('COPY observatory."{}" FROM stdin WITH CSV HEADER;\n'.format(tablename))
|
||||
|
||||
subprocess.check_call('''
|
||||
psql -c "COPY (SELECT {cols} \
|
||||
FROM observatory.{tablename} {where}) \
|
||||
TO STDOUT WITH CSV HEADER" >> {outfile}'''.format(
|
||||
cols=cols,
|
||||
tablename=tablename,
|
||||
where=where,
|
||||
outfile=OUTFILE_PATH,
|
||||
), shell=True)
|
||||
|
||||
with open(OUTFILE_PATH, 'a') as outfile:
|
||||
outfile.write('\\.\n\n')
|
||||
|
||||
|
||||
outfile.write('''
|
||||
ALTER TABLE observatory.obs_table
|
||||
ADD PRIMARY KEY (id);
|
||||
ALTER TABLE observatory.obs_column_table
|
||||
ADD PRIMARY KEY (column_id, table_id);
|
||||
CREATE UNIQUE INDEX ON observatory.obs_column_table (table_id, column_id);
|
||||
CREATE UNIQUE INDEX ON observatory.obs_column_table (table_id, colname);
|
||||
ALTER TABLE observatory.obs_column
|
||||
ADD PRIMARY KEY (id);
|
||||
ALTER TABLE observatory.obs_column_to_column
|
||||
ADD PRIMARY KEY (source_id, target_id, reltype);
|
||||
CREATE UNIQUE INDEX ON observatory.obs_column_to_column (target_id, source_id, reltype);
|
||||
CREATE INDEX ON observatory.obs_column_to_column (reltype);
|
||||
ALTER TABLE observatory.obs_column_tag
|
||||
ADD PRIMARY KEY (column_id, tag_id);
|
||||
CREATE UNIQUE INDEX ON observatory.obs_column_tag (tag_id, column_id);
|
||||
ALTER TABLE observatory.obs_tag
|
||||
ADD PRIMARY KEY (id);
|
||||
CREATE INDEX ON observatory.obs_tag (type);
|
||||
def main():
|
||||
unique_tables = set()
|
||||
|
||||
VACUUM ANALYZE observatory.obs_table;
|
||||
VACUUM ANALYZE observatory.obs_column_table;
|
||||
VACUUM ANALYZE observatory.obs_column;
|
||||
VACUUM ANALYZE observatory.obs_column_to_column;
|
||||
VACUUM ANALYZE observatory.obs_column_tag;
|
||||
VACUUM ANALYZE observatory.obs_tag;
|
||||
for f in FIXTURES:
|
||||
column_id, boundary_id, timespan = f
|
||||
tablename_query = get_tablename_query(column_id, boundary_id, timespan)
|
||||
resp = query(tablename_query).fetchone()
|
||||
if resp:
|
||||
tablename, colname, table_id = resp
|
||||
else:
|
||||
print("Could not find table for {}, {}, {}".format(
|
||||
column_id, boundary_id, timespan))
|
||||
continue
|
||||
table_colname = (tablename, colname, boundary_id, table_id, )
|
||||
if table_colname not in unique_tables:
|
||||
print(table_colname)
|
||||
unique_tables.add(table_colname)
|
||||
|
||||
CREATE TABLE observatory.obs_meta AS
|
||||
SELECT numer_c.id numer_id,
|
||||
denom_c.id denom_id,
|
||||
geom_c.id geom_id,
|
||||
MAX(numer_c.name) numer_name,
|
||||
MAX(denom_c.name) denom_name,
|
||||
MAX(geom_c.name) geom_name,
|
||||
MAX(numer_c.description) numer_description,
|
||||
MAX(denom_c.description) denom_description,
|
||||
MAX(geom_c.description) geom_description,
|
||||
MAX(numer_c.aggregate) numer_aggregate,
|
||||
MAX(denom_c.aggregate) denom_aggregate,
|
||||
MAX(geom_c.aggregate) geom_aggregate,
|
||||
MAX(numer_c.type) numer_type,
|
||||
MAX(denom_c.type) denom_type,
|
||||
MAX(geom_c.type) geom_type,
|
||||
MAX(numer_data_ct.colname) numer_colname,
|
||||
MAX(denom_data_ct.colname) denom_colname,
|
||||
MAX(geom_geom_ct.colname) geom_colname,
|
||||
MAX(numer_geomref_ct.colname) numer_geomref_colname,
|
||||
MAX(denom_geomref_ct.colname) denom_geomref_colname,
|
||||
MAX(geom_geomref_ct.colname) geom_geomref_colname,
|
||||
MAX(numer_t.tablename) numer_tablename,
|
||||
MAX(denom_t.tablename) denom_tablename,
|
||||
MAX(geom_t.tablename) geom_tablename,
|
||||
MAX(numer_t.timespan) numer_timespan,
|
||||
MAX(denom_t.timespan) denom_timespan,
|
||||
MAX(numer_c.weight) numer_weight,
|
||||
MAX(denom_c.weight) denom_weight,
|
||||
MAX(geom_c.weight) geom_weight,
|
||||
MAX(geom_t.timespan) geom_timespan,
|
||||
MAX(geom_t.the_geom_webmercator)::geometry AS the_geom_webmercator,
|
||||
ARRAY_AGG(DISTINCT s_tag.id) section_tags,
|
||||
ARRAY_AGG(DISTINCT ss_tag.id) subsection_tags,
|
||||
ARRAY_AGG(DISTINCT unit_tag.id) unit_tags
|
||||
FROM observatory.obs_column_table numer_data_ct,
|
||||
observatory.obs_table numer_t,
|
||||
observatory.obs_column_table numer_geomref_ct,
|
||||
observatory.obs_column geomref_c,
|
||||
observatory.obs_column_to_column geomref_c2c,
|
||||
observatory.obs_column geom_c,
|
||||
observatory.obs_column_table geom_geom_ct,
|
||||
observatory.obs_column_table geom_geomref_ct,
|
||||
observatory.obs_table geom_t,
|
||||
observatory.obs_column_tag ss_ctag,
|
||||
observatory.obs_tag ss_tag,
|
||||
observatory.obs_column_tag s_ctag,
|
||||
observatory.obs_tag s_tag,
|
||||
observatory.obs_column_tag unit_ctag,
|
||||
observatory.obs_tag unit_tag,
|
||||
observatory.obs_column numer_c
|
||||
LEFT JOIN (
|
||||
observatory.obs_column_to_column denom_c2c
|
||||
JOIN observatory.obs_column denom_c ON denom_c2c.target_id = denom_c.id
|
||||
JOIN observatory.obs_column_table denom_data_ct ON denom_data_ct.column_id = denom_c.id
|
||||
JOIN observatory.obs_table denom_t ON denom_data_ct.table_id = denom_t.id
|
||||
JOIN observatory.obs_column_table denom_geomref_ct ON denom_geomref_ct.table_id = denom_t.id
|
||||
) ON denom_c2c.source_id = numer_c.id
|
||||
WHERE numer_c.id = numer_data_ct.column_id
|
||||
AND numer_data_ct.table_id = numer_t.id
|
||||
AND numer_t.id = numer_geomref_ct.table_id
|
||||
AND numer_geomref_ct.column_id = geomref_c.id
|
||||
AND geomref_c2c.reltype = 'geom_ref'
|
||||
AND geomref_c.id = geomref_c2c.source_id
|
||||
AND geom_c.id = geomref_c2c.target_id
|
||||
AND geom_geomref_ct.column_id = geomref_c.id
|
||||
AND geom_geomref_ct.table_id = geom_t.id
|
||||
AND geom_geom_ct.column_id = geom_c.id
|
||||
AND geom_geom_ct.table_id = geom_t.id
|
||||
AND geom_c.type ILIKE 'geometry'
|
||||
AND numer_c.type NOT ILIKE 'geometry'
|
||||
AND numer_t.id != geom_t.id
|
||||
AND numer_c.id != geomref_c.id
|
||||
AND unit_tag.type = 'unit'
|
||||
AND ss_tag.type = 'subsection'
|
||||
AND s_tag.type = 'section'
|
||||
AND unit_ctag.column_id = numer_c.id
|
||||
AND unit_ctag.tag_id = unit_tag.id
|
||||
AND ss_ctag.column_id = numer_c.id
|
||||
AND ss_ctag.tag_id = ss_tag.id
|
||||
AND s_ctag.column_id = numer_c.id
|
||||
AND s_ctag.tag_id = s_tag.id
|
||||
AND (denom_c2c.reltype = 'denominator' OR denom_c2c.reltype IS NULL)
|
||||
AND (denom_geomref_ct.column_id = geomref_c.id OR denom_geomref_ct.column_id IS NULL)
|
||||
AND (denom_t.timespan = numer_t.timespan OR denom_t.timespan IS NULL)
|
||||
GROUP BY numer_c.id, denom_c.id, geom_c.id,
|
||||
numer_t.id, denom_t.id, geom_t.id;
|
||||
''')
|
||||
print unique_tables
|
||||
|
||||
dropfiles.write('''
|
||||
DROP TABLE IF EXISTS observatory.obs_meta;
|
||||
''')
|
||||
with open(OUTFILE_PATH, 'w') as outfile:
|
||||
outfile.write('SET client_min_messages TO WARNING;\n\\set ECHO none\n')
|
||||
outfile.write('CREATE SCHEMA IF NOT EXISTS observatory;\n\n')
|
||||
|
||||
with open(DROPFILE_PATH, 'w') as dropfile:
|
||||
dropfile.write('SET client_min_messages TO WARNING;\n\\set ECHO none\n')
|
||||
|
||||
for tablename in METADATA_TABLES:
|
||||
print(tablename)
|
||||
if tablename == 'obs_meta':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"(numer_id, geom_id, numer_timespan) = ('{}', '{}', '{}')".format(
|
||||
numer_id, geom_id, timespan)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_meta_numer':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"numer_id IN ('{}', '{}')".format(numer_id, geom_id)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_meta_denom':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"denom_id IN ('{}', '{}')".format(numer_id, geom_id)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_meta_geom':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"geom_id IN ('{}', '{}')".format(numer_id, geom_id)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_meta_timespan':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"timespan_id = ('{}')".format(timespan)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_column':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"id IN ('{}', '{}')".format(numer_id, geom_id)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_column_tag':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"column_id IN ('{}', '{}')".format(numer_id, geom_id)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_column_table':
|
||||
where = 'WHERE column_id IN ({numer_ids}) ' \
|
||||
'OR column_id IN ({geom_ids}) ' \
|
||||
'OR table_id IN ({table_ids}) '.format(
|
||||
numer_ids=','.join(["'{}'".format(x) for x, _, _ in FIXTURES]),
|
||||
geom_ids=','.join(["'{}'".format(x) for _, x, _ in FIXTURES]),
|
||||
table_ids=','.join(["'{}'".format(x) for _, _, _, x in unique_tables])
|
||||
)
|
||||
elif tablename == 'obs_column_to_column':
|
||||
where = "WHERE " + " OR ".join([
|
||||
"source_id IN ('{}', '{}') OR target_id IN ('{}', '{}')".format(
|
||||
numer_id, geom_id, numer_id, geom_id)
|
||||
for numer_id, geom_id, timespan in FIXTURES
|
||||
])
|
||||
elif tablename == 'obs_table':
|
||||
where = 'WHERE timespan IN ({timespans}) ' \
|
||||
'OR id IN ({table_ids}) '.format(
|
||||
timespans=','.join(["'{}'".format(x) for _, _, x in FIXTURES]),
|
||||
table_ids=','.join(["'{}'".format(x) for _, _, _, x in unique_tables])
|
||||
)
|
||||
else:
|
||||
where = ''
|
||||
dump('*', tablename, where)
|
||||
|
||||
for tablename, colname, boundary_id, table_id in unique_tables:
|
||||
if 'zcta5' in boundary_id:
|
||||
where = '\'11%\''
|
||||
compare = 'LIKE'
|
||||
elif 'whosonfirst' in boundary_id:
|
||||
where = '(\'85632785\',\'85633051\',\'85633111\',\'85633147\',\'85633253\',\'85633267\')'
|
||||
compare = 'IN'
|
||||
else:
|
||||
where = '\'36047%\''
|
||||
compare = 'LIKE'
|
||||
print ' '.join(['*', tablename, "WHERE {}::text {} {}".format(colname, compare, where)])
|
||||
dump('*', tablename, "WHERE {}::text {} {}".format(colname, compare, where))
|
||||
|
||||
if __name__ == '__main__':
|
||||
main()
|
||||
|
@ -203,3 +203,20 @@ BEGIN
|
||||
RETURN result;
|
||||
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 $$
|
||||
SELECT $1;
|
||||
$$;
|
||||
|
||||
DROP AGGREGATE IF EXISTS cdb_observatory.FIRST (anyelement);
|
||||
|
||||
-- And then wrap an aggregate around it
|
||||
CREATE AGGREGATE cdb_observatory.FIRST (
|
||||
sfunc = cdb_observatory.first_agg,
|
||||
basetype = anyelement,
|
||||
stype = anyelement
|
||||
);
|
||||
|
||||
|
@ -1,4 +1,4 @@
|
||||
-- return a table that contains a string match based on input
|
||||
|
||||
-- TODO: implement search for timespan
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory._OBS_SearchTables(
|
||||
@ -120,3 +120,280 @@ BEGIN
|
||||
RETURN;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Functions the interface works from to identify available numerators,
|
||||
-- denominators, geometries, and timespans
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetAvailableNumerators(
|
||||
bounds GEOMETRY DEFAULT NULL,
|
||||
filter_tags TEXT[] DEFAULT NULL,
|
||||
denom_id TEXT DEFAULT NULL,
|
||||
geom_id TEXT DEFAULT NULL,
|
||||
timespan TEXT DEFAULT NULL
|
||||
) 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
|
||||
geom_clause TEXT;
|
||||
BEGIN
|
||||
filter_tags := COALESCE(filter_tags, (ARRAY[])::TEXT[]);
|
||||
denom_id := COALESCE(denom_id, '');
|
||||
geom_id := COALESCE(geom_id, '');
|
||||
timespan := COALESCE(timespan, '');
|
||||
IF bounds IS NULL THEN
|
||||
geom_clause := '';
|
||||
ELSE
|
||||
geom_clause := 'ST_Intersects(the_geom, $5) AND';
|
||||
END IF;
|
||||
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
|
||||
WHERE %s (numer_tags ?& $4 OR CARDINALITY($4) = 0)
|
||||
$string$, geom_clause)
|
||||
USING denom_id, geom_id, timespan, filter_tags, bounds;
|
||||
RETURN;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetAvailableDenominators(
|
||||
bounds GEOMETRY DEFAULT NULL,
|
||||
filter_tags TEXT[] DEFAULT NULL,
|
||||
numer_id TEXT DEFAULT NULL,
|
||||
geom_id TEXT DEFAULT NULL,
|
||||
timespan TEXT DEFAULT NULL
|
||||
) RETURNS TABLE (
|
||||
denom_id TEXT,
|
||||
denom_name TEXT,
|
||||
denom_description TEXT,
|
||||
denom_weight NUMERIC,
|
||||
denom_license TEXT,
|
||||
denom_source TEXT,
|
||||
denom_type TEXT,
|
||||
denom_aggregate TEXT,
|
||||
denom_extra JSONB,
|
||||
denom_tags JSONB,
|
||||
valid_numer BOOLEAN,
|
||||
valid_geom BOOLEAN,
|
||||
valid_timespan BOOLEAN
|
||||
) AS $$
|
||||
DECLARE
|
||||
geom_clause TEXT;
|
||||
BEGIN
|
||||
filter_tags := COALESCE(filter_tags, (ARRAY[])::TEXT[]);
|
||||
numer_id := COALESCE(numer_id, '');
|
||||
geom_id := COALESCE(geom_id, '');
|
||||
timespan := COALESCE(timespan, '');
|
||||
IF bounds IS NULL THEN
|
||||
geom_clause := '';
|
||||
ELSE
|
||||
geom_clause := 'ST_Intersects(the_geom, $5) AND';
|
||||
END IF;
|
||||
RETURN QUERY
|
||||
EXECUTE
|
||||
format($string$
|
||||
SELECT denom_id::TEXT,
|
||||
denom_name::TEXT,
|
||||
denom_description::TEXT,
|
||||
denom_weight::NUMERIC,
|
||||
NULL::TEXT license,
|
||||
NULL::TEXT source,
|
||||
denom_type::TEXT,
|
||||
denom_aggregate::TEXT,
|
||||
denom_extra::JSONB,
|
||||
denom_tags::JSONB,
|
||||
$1 = ANY(numers) valid_numer,
|
||||
$2 = ANY(geoms) valid_geom,
|
||||
$3 = ANY(timespans) valid_timespan
|
||||
FROM observatory.obs_meta_denom
|
||||
WHERE %s (denom_tags ?& $4 OR CARDINALITY($4) = 0)
|
||||
$string$, geom_clause)
|
||||
USING numer_id, geom_id, timespan, filter_tags, bounds;
|
||||
RETURN;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetAvailableGeometries(
|
||||
bounds GEOMETRY DEFAULT NULL,
|
||||
filter_tags TEXT[] DEFAULT NULL,
|
||||
numer_id TEXT DEFAULT NULL,
|
||||
denom_id TEXT DEFAULT NULL,
|
||||
timespan TEXT DEFAULT NULL
|
||||
) RETURNS TABLE (
|
||||
geom_id TEXT,
|
||||
geom_name TEXT,
|
||||
geom_description TEXT,
|
||||
geom_weight NUMERIC,
|
||||
geom_aggregate TEXT,
|
||||
geom_license TEXT,
|
||||
geom_source TEXT,
|
||||
valid_numer BOOLEAN,
|
||||
valid_denom BOOLEAN,
|
||||
valid_timespan BOOLEAN
|
||||
) AS $$
|
||||
DECLARE
|
||||
geom_clause TEXT;
|
||||
BEGIN
|
||||
filter_tags := COALESCE(filter_tags, (ARRAY[])::TEXT[]);
|
||||
numer_id := COALESCE(numer_id, '');
|
||||
denom_id := COALESCE(denom_id, '');
|
||||
timespan := COALESCE(timespan, '');
|
||||
IF bounds IS NULL THEN
|
||||
geom_clause := '';
|
||||
ELSE
|
||||
geom_clause := 'ST_Intersects(the_geom, $5) AND';
|
||||
END IF;
|
||||
RETURN QUERY
|
||||
EXECUTE
|
||||
format($string$
|
||||
SELECT geom_id::TEXT,
|
||||
geom_name::TEXT,
|
||||
geom_description::TEXT,
|
||||
geom_weight::NUMERIC,
|
||||
NULL::TEXT geom_aggregate,
|
||||
NULL::TEXT license,
|
||||
NULL::TEXT source,
|
||||
$1 = ANY(numers) valid_numer,
|
||||
$2 = ANY(denoms) valid_denom,
|
||||
$3 = ANY(timespans) valid_timespan
|
||||
FROM observatory.obs_meta_geom
|
||||
WHERE %s (geom_tags ?& $4 OR CARDINALITY($4) = 0)
|
||||
$string$, geom_clause)
|
||||
USING numer_id, denom_id, timespan, filter_tags, bounds;
|
||||
RETURN;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_GetAvailableTimespans(
|
||||
bounds GEOMETRY DEFAULT NULL,
|
||||
filter_tags TEXT[] DEFAULT NULL,
|
||||
numer_id TEXT DEFAULT NULL,
|
||||
denom_id TEXT DEFAULT NULL,
|
||||
geom_id TEXT DEFAULT NULL
|
||||
) RETURNS TABLE (
|
||||
timespan_id TEXT,
|
||||
timespan_name TEXT,
|
||||
timespan_description TEXT,
|
||||
timespan_weight NUMERIC,
|
||||
timespan_aggregate TEXT,
|
||||
timespan_license TEXT,
|
||||
timespan_source TEXT,
|
||||
valid_numer BOOLEAN,
|
||||
valid_denom BOOLEAN,
|
||||
valid_geom BOOLEAN
|
||||
) AS $$
|
||||
DECLARE
|
||||
geom_clause TEXT;
|
||||
BEGIN
|
||||
filter_tags := COALESCE(filter_tags, (ARRAY[])::TEXT[]);
|
||||
numer_id := COALESCE(numer_id, '');
|
||||
denom_id := COALESCE(denom_id, '');
|
||||
geom_id := COALESCE(geom_id, '');
|
||||
IF bounds IS NULL THEN
|
||||
geom_clause := '';
|
||||
ELSE
|
||||
geom_clause := 'ST_Intersects(the_geom, $5) AND';
|
||||
END IF;
|
||||
RETURN QUERY
|
||||
EXECUTE
|
||||
format($string$
|
||||
SELECT timespan_id::TEXT,
|
||||
timespan_name::TEXT,
|
||||
timespan_description::TEXT,
|
||||
timespan_weight::NUMERIC,
|
||||
NULL::TEXT timespan_aggregate,
|
||||
NULL::TEXT license,
|
||||
NULL::TEXT source,
|
||||
$1 = ANY(numers) valid_numer,
|
||||
$2 = ANY(denoms) valid_denom,
|
||||
$3 = ANY(geoms) valid_geom_id
|
||||
FROM observatory.obs_meta_timespan
|
||||
WHERE %s (timespan_tags ?& $4 OR CARDINALITY($4) = 0)
|
||||
$string$, geom_clause)
|
||||
USING numer_id, denom_id, geom_id, filter_tags, bounds;
|
||||
RETURN;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
-- Function below should replace SQL in
|
||||
-- https://github.com/CartoDB/cartodb/blob/ab465cb2918c917940e955963b0cd8a050c06600/lib/assets/javascripts/cartodb3/editor/layers/layer-content-views/analyses/data-observatory-metadata.js
|
||||
CREATE OR REPLACE FUNCTION cdb_observatory.OBS_LegacyBuilderMetadata(
|
||||
aggregate_type TEXT DEFAULT NULL
|
||||
)
|
||||
RETURNS TABLE (
|
||||
name TEXT,
|
||||
subsection JSONB
|
||||
) AS $$
|
||||
DECLARE
|
||||
aggregate_condition TEXT DEFAULT '';
|
||||
BEGIN
|
||||
IF aggregate_type IS NOT NULL THEN
|
||||
aggregate_condition := format(' AND numer_aggregate = %L ', aggregate_type);
|
||||
END IF;
|
||||
RETURN QUERY
|
||||
EXECUTE format($string$
|
||||
WITH expanded_subsections AS (
|
||||
SELECT numer_id,
|
||||
numer_name,
|
||||
numer_tags,
|
||||
jsonb_each_text(numer_tags) as subsection_tag_id_name
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators()
|
||||
WHERE numer_weight > 0 %s
|
||||
), expanded_sections AS (
|
||||
SELECT JSONB_Agg(JSONB_Build_Object(
|
||||
'f1', JSONB_Build_Object('id', numer_id, 'name', numer_name))) columns,
|
||||
SUBSTR((subsection_tag_id_name).key, 12) subsection_id,
|
||||
(subsection_tag_id_name).value subsection_name,
|
||||
jsonb_each_text(numer_tags) as section_tag_id_name
|
||||
FROM expanded_subsections
|
||||
WHERE (subsection_tag_id_name).key LIKE 'subsection/%%'
|
||||
GROUP BY (subsection_tag_id_name).key, (subsection_tag_id_name).value,
|
||||
numer_tags
|
||||
), full_expansion AS (
|
||||
SELECT columns, subsection_id, subsection_name,
|
||||
SUBSTR((section_tag_id_name).key, 9) section_id,
|
||||
(section_tag_id_name).value section_name
|
||||
FROM expanded_sections
|
||||
WHERE (section_tag_id_name).key LIKE 'section/%%'
|
||||
)
|
||||
SELECT section_name AS name, JSONB_Agg(
|
||||
JSONB_Build_Object(
|
||||
'f1', JSONB_Build_Object(
|
||||
'name', subsection_name,
|
||||
'id', subsection_id,
|
||||
'columns', columns
|
||||
)
|
||||
)
|
||||
) as subsection
|
||||
FROM full_expansion
|
||||
GROUP BY section_name
|
||||
$string$, aggregate_condition);
|
||||
RETURN;
|
||||
END
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
@ -12,3 +12,147 @@ t
|
||||
_obs_getavailableboundariesexist
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_usa_pop_in_all
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_usa_pop_in_nyc_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_usa_pop_in_usa_extents
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_no_usa_pop_not_in_zero_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_usa_pop_in_age_gender_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_no_pop_in_income_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_male_pop_denom_by_total_pop
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_no_income_denom_by_total_pop
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_zillow_at_zcta5
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_no_zillow_at_block_group
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_total_pop_2010_2014
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablenumerators_no_total_pop_1996
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_usa_pop_in_all
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_usa_pop_in_nyc_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_usa_pop_in_usa_extents
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_no_usa_pop_not_in_zero_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_usa_pop_in_age_gender_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_no_pop_in_income_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_male_pop_denom_by_total_pop
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_no_income_denom_by_total_pop
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_at_zcta5
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_none_spanish_geom
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_total_pop_2010_2014
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabledenominators_no_total_pop_1996
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_usa_bg_in_all
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_usa_bg_in_nyc_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_usa_bg_in_usa_extents
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_no_usa_bg_not_in_zero_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_usa_bg_in_boundary_subsection
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_no_bg_in_uk_section
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_total_pop_in_usa_bg
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_foobarbaz_not_in_usa_bg
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_total_pop_denom_in_usa_bg
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_foobarbaz_denom_not_in_usa_bg
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_bg_2014
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_bg_not_1996
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabletimespans_2010_2014_in_all
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabletimespans_2010_2014_in_nyc_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabletimespans_2010_2014_in_usa_extents
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabletimespans_no_usa_bg_not_in_zero_point
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabletimespans_total_pop_in_2010_2014
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailabletimespans_foobarbaz_not_in_2010_2014
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_total_pop_denom_in_2010_2014
|
||||
t
|
||||
(1 row)
|
||||
_obs_getavailablegeometries_foobarbaz_denom_not_in_2010_2014
|
||||
t
|
||||
(1 row)
|
||||
_total_pop_in_legacy_builder_metadata
|
||||
t
|
||||
(1 row)
|
||||
_median_income_in_legacy_builder_metadata
|
||||
t
|
||||
(1 row)
|
||||
_total_pop_in_legacy_builder_metadata_sums
|
||||
t
|
||||
(1 row)
|
||||
_median_income_not_in_legacy_builder_metadata_sums
|
||||
t
|
||||
(1 row)
|
||||
|
32
src/pg/test/fixtures/drop_fixtures.sql
vendored
32
src/pg/test/fixtures/drop_fixtures.sql
vendored
@ -7,18 +7,22 @@ DROP TABLE IF EXISTS observatory.obs_column_tag;
|
||||
DROP TABLE IF EXISTS observatory.obs_tag;
|
||||
DROP TABLE IF EXISTS observatory.obs_column_to_column;
|
||||
DROP TABLE IF EXISTS observatory.obs_dump_version;
|
||||
DROP TABLE IF EXISTS observatory.obs_65f29658e096ca1485bf683f65fdbc9f05ec3c5d;
|
||||
DROP TABLE IF EXISTS observatory.obs_1746e37b7cd28cb131971ea4187d42d71f09c5f3;
|
||||
DROP TABLE IF EXISTS observatory.obs_1a098da56badf5f32e336002b0a81708c40d29cd;
|
||||
DROP TABLE IF EXISTS observatory.obs_7615e8622a68bfc5fe37c69c9880edfb40250103;
|
||||
DROP TABLE IF EXISTS observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81;
|
||||
DROP TABLE IF EXISTS observatory.obs_8764a6b439a4f8714f54d4b3a157bc5e36519066;
|
||||
DROP TABLE IF EXISTS observatory.obs_b393b5b88c6adda634b2071a8005b03c551b609a;
|
||||
DROP TABLE IF EXISTS observatory.obs_1ea93bbc109c87c676b3270789dacf7a1430db6c;
|
||||
DROP TABLE IF EXISTS observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7;
|
||||
DROP TABLE IF EXISTS observatory.obs_6c1309a64d8f3e6986061f4d1ca7b57743e75e74;
|
||||
DROP TABLE IF EXISTS observatory.obs_d39f7fe5959891c8296490d83c22ded31c54af13;
|
||||
DROP TABLE IF EXISTS observatory.obs_144e8b4f906885b2e057ac4842644a553ae49c6e;
|
||||
DROP TABLE IF EXISTS observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308;
|
||||
|
||||
DROP TABLE IF EXISTS observatory.obs_meta;
|
||||
DROP TABLE IF EXISTS observatory.obs_meta_numer;
|
||||
DROP TABLE IF EXISTS observatory.obs_meta_denom;
|
||||
DROP TABLE IF EXISTS observatory.obs_meta_geom;
|
||||
DROP TABLE IF EXISTS observatory.obs_meta_timespan;
|
||||
DROP TABLE IF EXISTS observatory.obs_fcd4e4f5610f6764973ef8c0c215b2e80bec8963;
|
||||
DROP TABLE IF EXISTS observatory.obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308;
|
||||
DROP TABLE IF EXISTS observatory.obs_6c1309a64d8f3e6986061f4d1ca7b57743e75e74;
|
||||
DROP TABLE IF EXISTS observatory.obs_7615e8622a68bfc5fe37c69c9880edfb40250103;
|
||||
DROP TABLE IF EXISTS observatory.obs_d39f7fe5959891c8296490d83c22ded31c54af13;
|
||||
DROP TABLE IF EXISTS observatory.obs_1babf5a26a1ecda5fb74963e88408f71d0364b81;
|
||||
DROP TABLE IF EXISTS observatory.obs_65f29658e096ca1485bf683f65fdbc9f05ec3c5d;
|
||||
DROP TABLE IF EXISTS observatory.obs_144e8b4f906885b2e057ac4842644a553ae49c6e;
|
||||
DROP TABLE IF EXISTS observatory.obs_fc050f0b8673cfe3c6aa1040f749eb40975691b7;
|
||||
DROP TABLE IF EXISTS observatory.obs_1a098da56badf5f32e336002b0a81708c40d29cd;
|
||||
DROP TABLE IF EXISTS observatory.obs_1ea93bbc109c87c676b3270789dacf7a1430db6c;
|
||||
DROP TABLE IF EXISTS observatory.obs_b393b5b88c6adda634b2071a8005b03c551b609a;
|
||||
DROP TABLE IF EXISTS observatory.obs_1746e37b7cd28cb131971ea4187d42d71f09c5f3;
|
||||
DROP TABLE IF EXISTS observatory.obs_a01cd5d8ccaa6531cef715071e9307e6b1987ec3;
|
||||
|
42163
src/pg/test/fixtures/load_fixtures.sql
vendored
42163
src/pg/test/fixtures/load_fixtures.sql
vendored
File diff suppressed because one or more lines are too long
@ -67,7 +67,7 @@ FROM cte;
|
||||
SELECT
|
||||
(cdb_observatory._OBS_GetPoints(
|
||||
ST_SetSRID(ST_Point(0, 0), 4326),
|
||||
'obs_1a098da56badf5f32e336002b0a81708c40d29cd'::text, -- see example in obs_geomtable
|
||||
'obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308'::text, -- see example in obs_geomtable
|
||||
(Array['{"colname":"total_pop","tablename":"obs_1a098da56badf5f32e336002b0a81708c40d29cd","aggregate":"sum","name":"Total Population","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'::json])
|
||||
))[1]::text is null
|
||||
as OBS_GetPoints_for_null_island;
|
||||
@ -89,7 +89,7 @@ SELECT
|
||||
SELECT
|
||||
((cdb_observatory._OBS_GetPolygons(
|
||||
ST_Buffer(ST_SetSRID(ST_Point(0, 0), 4326)::geography, 500)::geometry,
|
||||
'obs_1a098da56badf5f32e336002b0a81708c40d29cd'::text, -- see example in obs_geomtable
|
||||
'obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308'::text, -- see example in obs_geomtable
|
||||
Array['{"colname":"total_pop","tablename":"obs_1a098da56badf5f32e336002b0a81708c40d29cd","aggregate":"sum","name":"Total Population","type":"Numeric","description":"The total number of all people living in a given geographic area. This is a very useful catch-all denominator when calculating rates."}'::json])
|
||||
)[1]->>'value') is null
|
||||
as OBS_GetPolygons_for_null_island;
|
||||
@ -129,15 +129,15 @@ WITH result as (
|
||||
from result;
|
||||
|
||||
-- Point-based OBS_GetMeasure with zillow
|
||||
SELECT abs(OBS_GetMeasure_zhvi_point - 583600) / 583600 < 0.001 AS OBS_GetMeasure_zhvi_point_test FROM cdb_observatory.OBS_GetMeasure(
|
||||
SELECT abs(OBS_GetMeasure_zhvi_point - 597900) / 597900 < 5.0 AS OBS_GetMeasure_zhvi_point_test FROM cdb_observatory.OBS_GetMeasure(
|
||||
ST_SetSRID(ST_Point(-73.94602417945862, 40.6768220087458), 4326),
|
||||
'us.zillow.AllHomes_Zhvi', null, 'us.census.tiger.zcta5', '2014-01'
|
||||
) As t(OBS_GetMeasure_zhvi_point);
|
||||
|
||||
-- Point-based OBS_GetMeasure with zillow default to latest
|
||||
SELECT abs(OBS_GetMeasure_zhvi_point_default_latest - 972900) / 972900 < 0.001 AS OBS_GetMeasure_zhvi_point_default_latest_test FROM cdb_observatory.OBS_GetMeasure(
|
||||
-- Point-based OBS_GetMeasure with later measure
|
||||
SELECT abs(OBS_GetMeasure_zhvi_point_default_latest - 995400) / 995400 < 5.0 AS OBS_GetMeasure_zhvi_point_default_latest_test FROM cdb_observatory.OBS_GetMeasure(
|
||||
ST_SetSRID(ST_Point(-73.94602417945862, 40.6768220087458), 4326),
|
||||
'us.zillow.AllHomes_Zhvi'
|
||||
'us.zillow.AllHomes_Zhvi', null, 'us.census.tiger.zcta5', '2016-06'
|
||||
) As t(OBS_GetMeasure_zhvi_point_default_latest);
|
||||
|
||||
-- Point-based OBS_GetMeasure, default normalization (area)
|
||||
|
@ -33,3 +33,338 @@ SELECT COUNT(*) > 0 AS _OBS_GetAvailableBoundariesExist
|
||||
FROM cdb_observatory.OBS_GetAvailableBoundaries(
|
||||
cdb_observatory._TestPoint()
|
||||
) AS t(boundary_id, description, time_span, tablename);
|
||||
|
||||
--
|
||||
-- OBS_GetAvailableNumerators tests
|
||||
--
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators())
|
||||
AS _obs_getavailablenumerators_usa_pop_in_all;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailablenumerators_usa_pop_in_nyc_point;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakeEnvelope(
|
||||
-169.8046875, 21.289374355860424,
|
||||
-47.4609375, 72.0739114882038
|
||||
), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailablenumerators_usa_pop_in_usa_extents;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(0, 0), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailablenumerators_no_usa_pop_not_in_zero_point;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ARRAY['subsection/tags.age_gender']
|
||||
))
|
||||
AS _obs_getavailablenumerators_usa_pop_in_age_gender_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ARRAY['subsection/tags.income']
|
||||
))
|
||||
AS _obs_getavailablenumerators_no_pop_in_income_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01001002' IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'us.census.acs.B01003001'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getavailablenumerators_male_pop_denom_by_total_pop;
|
||||
|
||||
SELECT 'us.census.acs.B19013001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'us.census.acs.B01003001'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getavailablenumerators_no_income_denom_by_total_pop;
|
||||
|
||||
SELECT 'us.zillow.AllHomes_Zhvi' IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'us.census.tiger.zcta5'
|
||||
) WHERE valid_geom = True)
|
||||
AS _obs_getavailablenumerators_zillow_at_zcta5;
|
||||
|
||||
SELECT 'us.zillow.AllHomes_Zhvi' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'us.census.tiger.block_group'
|
||||
) WHERE valid_geom = True)
|
||||
AS _obs_getavailablenumerators_no_zillow_at_block_group;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, '2010 - 2014'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getavailablenumerators_total_pop_2010_2014;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT numer_id
|
||||
FROM cdb_observatory.OBS_GetAvailableNumerators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, '1996'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getavailablenumerators_no_total_pop_1996;
|
||||
|
||||
--
|
||||
-- OBS_GetAvailableDenominators tests
|
||||
--
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators())
|
||||
AS _obs_getavailabledenominators_usa_pop_in_all;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailabledenominators_usa_pop_in_nyc_point;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakeEnvelope(
|
||||
-169.8046875, 21.289374355860424,
|
||||
-47.4609375, 72.0739114882038
|
||||
), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailabledenominators_usa_pop_in_usa_extents;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(0, 0), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailabledenominators_no_usa_pop_not_in_zero_point;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ARRAY['subsection/tags.age_gender']
|
||||
))
|
||||
AS _obs_getavailabledenominators_usa_pop_in_age_gender_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ARRAY['subsection/tags.income']
|
||||
))
|
||||
AS _obs_getavailabledenominators_no_pop_in_income_subsection;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'us.census.acs.B01001002'
|
||||
) WHERE valid_numer = True)
|
||||
AS _obs_getavailabledenominators_male_pop_denom_by_total_pop;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'us.census.acs.B19013001'
|
||||
) WHERE valid_numer = True)
|
||||
AS _obs_getavailabledenominators_no_income_denom_by_total_pop;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'us.census.tiger.zcta5'
|
||||
) WHERE valid_geom = True)
|
||||
AS _obs_getavailabledenominators_at_zcta5;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'es.ine.the_geom'
|
||||
) WHERE valid_geom = True)
|
||||
AS _obs_getavailabledenominators_none_spanish_geom;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, '2010 - 2014'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getavailabledenominators_total_pop_2010_2014;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' NOT IN (SELECT denom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableDenominators(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, '1996'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getavailabledenominators_no_total_pop_1996;
|
||||
|
||||
--
|
||||
-- OBS_GetAvailableGeometries tests
|
||||
--
|
||||
|
||||
SELECT 'us.census.tiger.block_group' IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries())
|
||||
AS _obs_getavailablegeometries_usa_bg_in_all;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailablegeometries_usa_bg_in_nyc_point;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakeEnvelope(
|
||||
-169.8046875, 21.289374355860424,
|
||||
-47.4609375, 72.0739114882038
|
||||
), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailablegeometries_usa_bg_in_usa_extents;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' NOT IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(0, 0), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailablegeometries_no_usa_bg_not_in_zero_point;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ARRAY['subsection/tags.boundary']
|
||||
))
|
||||
AS _obs_getavailablegeometries_usa_bg_in_boundary_subsection;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' NOT IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
ARRAY['section/tags.uk']
|
||||
))
|
||||
AS _obs_getavailablegeometries_no_bg_in_uk_section;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'us.census.acs.B01003001'
|
||||
) WHERE valid_numer = True)
|
||||
AS _obs_getavailablegeometries_total_pop_in_usa_bg;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' NOT IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'foo.bar.baz'
|
||||
) WHERE valid_numer = True)
|
||||
AS _obs_getavailablegeometries_foobarbaz_not_in_usa_bg;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'us.census.acs.B01003001'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getavailablegeometries_total_pop_denom_in_usa_bg;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' NOT IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'foo.bar.baz'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getavailablegeometries_foobarbaz_denom_not_in_usa_bg;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, '2014'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getavailablegeometries_bg_2014;
|
||||
|
||||
SELECT 'us.census.tiger.block_group' NOT IN (SELECT geom_id
|
||||
FROM cdb_observatory.OBS_GetAvailableGeometries(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, '1996'
|
||||
) WHERE valid_timespan = True)
|
||||
AS _obs_getavailablegeometries_bg_not_1996;
|
||||
|
||||
--
|
||||
-- OBS_GetAvailableTimespans tests
|
||||
--
|
||||
|
||||
SELECT '2010 - 2014' IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans())
|
||||
AS _obs_getavailabletimespans_2010_2014_in_all;
|
||||
|
||||
SELECT '2010 - 2014' IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailabletimespans_2010_2014_in_nyc_point;
|
||||
|
||||
SELECT '2010 - 2014' IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans(
|
||||
ST_SetSRID(ST_MakeEnvelope(
|
||||
-169.8046875, 21.289374355860424,
|
||||
-47.4609375, 72.0739114882038
|
||||
), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailabletimespans_2010_2014_in_usa_extents;
|
||||
|
||||
SELECT '2010 - 2014' NOT IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans(
|
||||
ST_SetSRID(ST_MakePoint(0, 0), 4326),
|
||||
NULL, NULL, NULL, NULL
|
||||
)) AS _obs_getavailabletimespans_no_usa_bg_not_in_zero_point;
|
||||
|
||||
SELECT '2010 - 2014' IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'us.census.acs.B01003001'
|
||||
) WHERE valid_numer = True)
|
||||
AS _obs_getavailabletimespans_total_pop_in_2010_2014;
|
||||
|
||||
SELECT '2010 - 2014' NOT IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, 'foo.bar.baz'
|
||||
) WHERE valid_numer = True)
|
||||
AS _obs_getavailabletimespans_foobarbaz_not_in_2010_2014;
|
||||
|
||||
SELECT '2010 - 2014' IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'us.census.acs.B01003001'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getavailablegeometries_total_pop_denom_in_2010_2014;
|
||||
|
||||
SELECT '2010 - 2014' NOT IN (SELECT timespan_id
|
||||
FROM cdb_observatory.OBS_GetAvailableTimespans(
|
||||
ST_SetSRID(ST_MakePoint(-73.9, 40.7), 4326),
|
||||
NULL, NULL, 'foo.bar.baz'
|
||||
) WHERE valid_denom = True)
|
||||
AS _obs_getavailablegeometries_foobarbaz_denom_not_in_2010_2014;
|
||||
|
||||
-- OBS_LegacyBuilderMetadata tests
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT
|
||||
(jsonb_array_elements(((jsonb_array_elements(subsection))->'f1')->'columns')->'f1')->>'id' AS id
|
||||
FROM cdb_observatory.OBS_LegacyBuilderMetadata()
|
||||
) AS _total_pop_in_legacy_builder_metadata;
|
||||
|
||||
SELECT 'us.census.acs.B19013001' IN (SELECT
|
||||
(jsonb_array_elements(((jsonb_array_elements(subsection))->'f1')->'columns')->'f1')->>'id' AS id
|
||||
FROM cdb_observatory.OBS_LegacyBuilderMetadata()
|
||||
) AS _median_income_in_legacy_builder_metadata;
|
||||
|
||||
SELECT 'us.census.acs.B01003001' IN (SELECT
|
||||
(jsonb_array_elements(((jsonb_array_elements(subsection))->'f1')->'columns')->'f1')->>'id' AS id
|
||||
FROM cdb_observatory.OBS_LegacyBuilderMetadata('sum')
|
||||
) AS _total_pop_in_legacy_builder_metadata_sums;
|
||||
|
||||
SELECT 'us.census.acs.B19013001' NOT IN (SELECT
|
||||
(jsonb_array_elements(((jsonb_array_elements(subsection))->'f1')->'columns')->'f1')->>'id' AS id
|
||||
FROM cdb_observatory.OBS_LegacyBuilderMetadata('sum')
|
||||
) AS _median_income_not_in_legacy_builder_metadata_sums;
|
||||
|
||||
|
Loading…
Reference in New Issue
Block a user