From 38a784b15ce35561db945d7f3aa2831aca343a1a Mon Sep 17 00:00:00 2001 From: John Krauss Date: Wed, 13 Apr 2016 14:07:28 -0400 Subject: [PATCH] bring back lost obs_getcolumndata work from 94169e6874f2a79f2b6ed4d58ad0fd542a4ec64e --- src/pg/sql/40_observatory_utility.sql | 26 ++++++++++++++++------ src/pg/sql/41_observatory_augmentation.sql | 4 ++-- 2 files changed, 21 insertions(+), 9 deletions(-) diff --git a/src/pg/sql/40_observatory_utility.sql b/src/pg/sql/40_observatory_utility.sql index f119333..3f3b06d 100644 --- a/src/pg/sql/40_observatory_utility.sql +++ b/src/pg/sql/40_observatory_utility.sql @@ -56,15 +56,17 @@ BEGIN WHERE c2c.reltype = ''geom_ref'' AND c2c.target_id = $1 AND c2c.source_id = t.column_id - ) - SELECT array_agg(ROW(colname, tablename, aggregate)::OBS_ColumnData order by column_id) - FROM observatory.OBS_column c, observatory.OBS_column_table ct, observatory.OBS_table t - WHERE c.id = ct.column_id + ), + column_ids as ( + select row_number() over () as no, a.column_id as column_id from (select unnest($2) as column_id) a + ) + SELECT array_agg(ROW(colname, tablename, aggregate)::OBS_ColumnData order by column_ids.no) + FROM column_ids, observatory.OBS_column c, observatory.OBS_column_table ct, observatory.OBS_table t + WHERE column_ids.column_id = c.id + AND c.id = ct.column_id AND t.id = ct.table_id - AND Array[c.id] <@ $2 AND t.timespan = $3 AND t.id in (SELECT id FROM geomref) - ' USING geometry_id, column_ids, timespan INTO result; @@ -86,7 +88,17 @@ DECLARE column_id text; result text; BEGIN - EXECUTE format('select array_agg(column_id) from observatory.OBS_column_table where Array[colname] <@ $1 and table_id = %L limit 1', table_name) + EXECUTE format(' + WITH col_names AS ( + select row_number() over() as no, a.column_name as column_name from( + select unnest($1) as column_name + ) a + ) + select array_agg(column_id order by col_names.no) + FROM observatory.OBS_column_table,col_names + where colname = col_names.column_name + and table_id = %L limit 1 + ', table_name) INTO result using column_names; RETURN result; diff --git a/src/pg/sql/41_observatory_augmentation.sql b/src/pg/sql/41_observatory_augmentation.sql index 37fd27f..a848216 100644 --- a/src/pg/sql/41_observatory_augmentation.sql +++ b/src/pg/sql/41_observatory_augmentation.sql @@ -245,8 +245,8 @@ BEGIN ids := OBS_LookupCensusHuman(dimension_names); - RETURN QUERY SELECT names, vals - FROM OBS_Get(geom, ids, time_span, geometry_level); + RETURN QUERY + SELECT names, vals FROM OBS_Get(geom, ids, time_span, geometry_level); END; $$ LANGUAGE plpgsql;