faster generation of obs-meta via indexes
This commit is contained in:
parent
fe6343c73f
commit
897cf38d42
@ -93,8 +93,28 @@ with open('src/pg/test/fixtures/load_fixtures.sql', 'w') as outfile:
|
||||
|
||||
|
||||
outfile.write('''
|
||||
CREATE TABLE observatory.obs_meta AS
|
||||
SELECT numer_c.id numer_id,
|
||||
ALTER TABLE observatory.obs_table
|
||||
ADD PRIMARY KEY (id);
|
||||
ALTER TABLE observatory.obs_column_table
|
||||
ADD PRIMARY KEY (column_id, table_id),
|
||||
ADD FOREIGN KEY (column_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE,
|
||||
ADD FOREIGN KEY (table_id) REFERENCES observatory.obs_table(id) ON DELETE CASCADE;
|
||||
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),
|
||||
ADD FOREIGN KEY (source_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE,
|
||||
ADD FOREIGN KEY (target_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE;
|
||||
ALTER TABLE observatory.obs_column_tag
|
||||
ADD PRIMARY KEY (column_id, tag_id),
|
||||
ADD FOREIGN KEY (column_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE,
|
||||
ADD FOREIGN KEY (tag_id) REFERENCES observatory.obs_tag(id) ON DELETE CASCADE;
|
||||
ALTER TABLE observatory.obs_tag
|
||||
ADD PRIMARY KEY (id);
|
||||
|
||||
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,
|
||||
@ -128,7 +148,7 @@ with open('src/pg/test/fixtures/load_fixtures.sql', 'w') as outfile:
|
||||
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,
|
||||
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,
|
||||
@ -151,7 +171,7 @@ with open('src/pg/test/fixtures/load_fixtures.sql', 'w') as outfile:
|
||||
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
|
||||
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
|
||||
@ -178,10 +198,10 @@ with open('src/pg/test/fixtures/load_fixtures.sql', 'w') as outfile:
|
||||
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,
|
||||
GROUP BY numer_c.id, denom_c.id, geom_c.id,
|
||||
numer_t.id, denom_t.id, geom_t.id;
|
||||
''')
|
||||
|
||||
dropfiles.write('''
|
||||
DROP TABLE IF EXISTS observatory.obs_meta
|
||||
DROP TABLE IF EXISTS observatory.obs_meta;
|
||||
''')
|
||||
|
3
src/pg/test/fixtures/drop_fixtures.sql
vendored
3
src/pg/test/fixtures/drop_fixtures.sql
vendored
@ -21,5 +21,4 @@ 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;
|
||||
|
35
src/pg/test/fixtures/load_fixtures.sql
vendored
35
src/pg/test/fixtures/load_fixtures.sql
vendored
@ -25205,10 +25205,30 @@ cartodb_id,the_geom,the_geom_webmercator,geoid,aland,awater
|
||||
140587,0106000020E610000001000000010300000001000000090000005187156EF98052C0594B0169FF4D44406B459BE3DC8052C07F4E417E364E4440213EB0E3BF8052C0AA0EB9196E4E44402DCF83BBB38052C0DBDD03745F4E44401570CFF3A78052C0D07AF832514E44404835ECF7C48052C0A5BA8097194E4440FDF2C98AE18052C0C1A6CEA3E24D44405D18E945ED8052C08B1A4CC3F04D44405187156EF98052C0594B0169FF4D4440,0106000020110F00000100000001030000000100000009000000BDFCFB423A6E5FC1405BF4E2C2E652415E6A32C8096E5FC17238A38200E7524104CEEC85D86D5FC1AADFE0B83EE752412BC595DFC36D5FC16588C5552EE75241627B1BDDAF6D5FC1FEE34F631EE7524187F38026E16D5FC1760D482DE0E65241753D8AAF116E5FC1BF2D58B3A2E65241E3F3A49C256E5FC1DA4D0F80B2E65241BDFCFB423A6E5FC1405BF4E2C2E65241,360470170002,75411,0
|
||||
\.
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS "observatory";
|
||||
ALTER TABLE "obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308" SET SCHEMA "observatory";
|
||||
CREATE TABLE observatory.obs_meta AS
|
||||
SELECT numer_c.id numer_id,
|
||||
ALTER TABLE observatory.obs_table
|
||||
ADD PRIMARY KEY (id);
|
||||
ALTER TABLE observatory.obs_column_table
|
||||
ADD PRIMARY KEY (column_id, table_id),
|
||||
ADD FOREIGN KEY (column_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE,
|
||||
ADD FOREIGN KEY (table_id) REFERENCES observatory.obs_table(id) ON DELETE CASCADE;
|
||||
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),
|
||||
ADD FOREIGN KEY (source_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE,
|
||||
ADD FOREIGN KEY (target_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE;
|
||||
ALTER TABLE observatory.obs_column_tag
|
||||
ADD PRIMARY KEY (column_id, tag_id),
|
||||
ADD FOREIGN KEY (column_id) REFERENCES observatory.obs_column(id) ON DELETE CASCADE,
|
||||
ADD FOREIGN KEY (tag_id) REFERENCES observatory.obs_tag(id) ON DELETE CASCADE;
|
||||
ALTER TABLE observatory.obs_tag
|
||||
ADD PRIMARY KEY (id);
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS "observatory";
|
||||
ALTER TABLE "obs_c6fb99c47d61289fbb8e561ff7773799d3fcc308" SET SCHEMA "observatory";
|
||||
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,
|
||||
@ -25242,7 +25262,7 @@ cartodb_id,the_geom,the_geom_webmercator,geoid,aland,awater
|
||||
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,
|
||||
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,
|
||||
@ -25265,7 +25285,7 @@ cartodb_id,the_geom,the_geom_webmercator,geoid,aland,awater
|
||||
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
|
||||
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
|
||||
@ -25292,6 +25312,5 @@ cartodb_id,the_geom,the_geom_webmercator,geoid,aland,awater
|
||||
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,
|
||||
GROUP BY numer_c.id, denom_c.id, geom_c.id,
|
||||
numer_t.id, denom_t.id, geom_t.id;
|
||||
|
Loading…
Reference in New Issue
Block a user