From 0f8c7c4e29a102c55b8a3ba03b05c2a977aae259 Mon Sep 17 00:00:00 2001 From: Agnieszka Figiel Date: Fri, 11 Jan 2019 12:58:58 +0000 Subject: [PATCH] Display ZERO_DEFORESTATION as text, rather than convert to boolean --- app/models/api/v3/readonly/download_flow.rb | 2 +- ...wnload_flows_mv_to_handle_new_zd_values.rb | 8 + db/structure.sql | 39 ++--- db/views/download_flows_mv_v04.sql | 138 ++++++++++++++++++ 4 files changed, 161 insertions(+), 26 deletions(-) create mode 100644 db/migrate/20190111121850_update_download_flows_mv_to_handle_new_zd_values.rb create mode 100644 db/views/download_flows_mv_v04.sql diff --git a/app/models/api/v3/readonly/download_flow.rb b/app/models/api/v3/readonly/download_flow.rb index 0ac763fc1e..541ab6a97a 100644 --- a/app/models/api/v3/readonly/download_flow.rb +++ b/app/models/api/v3/readonly/download_flow.rb @@ -30,7 +30,7 @@ # attribute_name :text # attribute_name_with_unit :text # display_name :text -# bool_and :boolean +# text_values :text # sum :float # total :text # diff --git a/db/migrate/20190111121850_update_download_flows_mv_to_handle_new_zd_values.rb b/db/migrate/20190111121850_update_download_flows_mv_to_handle_new_zd_values.rb new file mode 100644 index 0000000000..8dd2e5bdae --- /dev/null +++ b/db/migrate/20190111121850_update_download_flows_mv_to_handle_new_zd_values.rb @@ -0,0 +1,8 @@ +class UpdateDownloadFlowsMvToHandleNewZdValues < ActiveRecord::Migration[5.2] + def change + update_view :download_flows_mv, + version: 4, + revert_to_version: 3, + materialized: true + end +end diff --git a/db/structure.sql b/db/structure.sql index 23ae3b6b62..e4a3c91878 100644 --- a/db/structure.sql +++ b/db/structure.sql @@ -2109,11 +2109,10 @@ CREATE MATERIALIZED VIEW public.download_flows_mv AS fi.name AS attribute_name, fi.name_with_unit AS attribute_name_with_unit, fi.display_name, - bool_and(fi.boolean_value) AS bool_and, + string_agg(fi.text_value, ' / '::text) AS text_values, sum(fi.numeric_value) AS sum, CASE - WHEN ((fi.attribute_type = 'Qual'::text) AND bool_and(fi.boolean_value)) THEN 'yes'::text - WHEN ((fi.attribute_type = 'Qual'::text) AND (NOT bool_and(fi.boolean_value))) THEN 'no'::text + WHEN (fi.attribute_type = 'Qual'::text) THEN string_agg(fi.text_value, ' / '::text) ELSE (sum(fi.numeric_value))::text END AS total FROM ((((((((public.flow_paths_mv f_0 @@ -2128,11 +2127,7 @@ CREATE MATERIALIZED VIEW public.download_flows_mv AS f.qual_id AS attribute_id, 'Qual'::text AS attribute_type, NULL::double precision AS numeric_value, - CASE - WHEN (lower(f.value) = 'yes'::text) THEN true - WHEN (lower(f.value) = 'no'::text) THEN false - ELSE NULL::boolean - END AS boolean_value, + f.value AS text_value, q.name, NULL::text AS unit, q.name AS name_with_unit, @@ -2146,9 +2141,9 @@ CREATE MATERIALIZED VIEW public.download_flows_mv AS UNION ALL SELECT f.flow_id, f.quant_id, - 'Quant'::text AS text, + 'Quant'::text, f.value, - NULL::boolean AS bool, + NULL::text, q.name, q.unit, CASE @@ -4833,20 +4828,6 @@ CREATE UNIQUE INDEX download_flows_mv_row_name_attribute_type_attribute_id_idx O CREATE INDEX flow_inds_ind_id_idx ON public.flow_inds USING btree (ind_id); --- --- Name: flow_paths_mv_flow_id_idx; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX flow_paths_mv_flow_id_idx ON public.flow_paths_mv USING btree (flow_id); - - --- --- Name: flow_paths_mv_flow_id_position_idx; Type: INDEX; Schema: public; Owner: - --- - -CREATE INDEX flow_paths_mv_flow_id_position_idx ON public.flow_paths_mv USING btree (flow_id, column_position); - - -- -- Name: flow_quals_qual_id_idx; Type: INDEX; Schema: public; Owner: - -- @@ -5099,6 +5080,13 @@ CREATE UNIQUE INDEX index_download_versions_on_context_id_and_is_current ON publ CREATE INDEX index_flow_inds_on_flow_id ON public.flow_inds USING btree (flow_id); +-- +-- Name: index_flow_paths_mv_on_flow_id_and_column_position; Type: INDEX; Schema: public; Owner: - +-- + +CREATE INDEX index_flow_paths_mv_on_flow_id_and_column_position ON public.flow_paths_mv USING btree (flow_id, column_position); + + -- -- Name: index_flow_quals_on_flow_id; Type: INDEX; Schema: public; Owner: - -- @@ -6044,6 +6032,7 @@ INSERT INTO "schema_migrations" (version) VALUES ('20181119104937'), ('20181119105000'), ('20181119105010'), -('20181119105022'); +('20181119105022'), +('20190111121850'); diff --git a/db/views/download_flows_mv_v04.sql b/db/views/download_flows_mv_v04.sql new file mode 100644 index 0000000000..c2385f36e0 --- /dev/null +++ b/db/views/download_flows_mv_v04.sql @@ -0,0 +1,138 @@ +SELECT + ARRAY[ + f_0.context_id, + f_0.year, + f_0.node_id, + f_1.node_id, + f_2.node_id, + f_3.node_id, + f_4.node_id, + f_5.node_id, + f_6.node_id, + f_7.node_id, + f_0.flow_id + ] AS row_name, + f_0.flow_id AS id, + f_0.context_id, + f_0.year, + f_0.name AS name_0, + f_1.name AS name_1, + f_2.name AS name_2, + f_3.name AS name_3, + f_4.name AS name_4, + f_5.name AS name_5, + f_6.name AS name_6, + f_7.name AS name_7, + f_0.node_id AS node_id_0, + f_1.node_id AS node_id_1, + f_2.node_id AS node_id_2, + f_3.node_id AS node_id_3, + f_4.node_id AS node_id_4, + f_5.node_id AS node_id_5, + f_6.node_id AS node_id_6, + f_7.node_id AS node_id_7, + CASE + WHEN f_5.node_type_name = 'EXPORTER' THEN f_5.node_id -- BRAZIL-SOY + WHEN f_2.node_type_name = 'EXPORTER' THEN f_2.node_id -- PARAGUAY-SOY, BRAZIL-BEEF + WHEN f_2.node_type_name = 'TRADER' THEN f_2.node_id -- ARGENTINE-SOY, ARGENTINA-BEEF, PARAGUAY-BEEF + WHEN f_1.node_type_name = 'EXPORTER' THEN f_1.node_id -- INDONESIA-PALM OIL + END AS exporter_node_id, + CASE + WHEN f_6.node_type_name = 'IMPORTER' THEN f_6.node_id -- BRAZIL-SOY + WHEN f_3.node_type_name = 'IMPORTER' THEN f_3.node_id -- BRAZIL-BEEF + WHEN f_2.node_type_name = 'IMPORTER' THEN f_2.node_id -- INDONESIA-PALM OIL + ELSE NULL -- OTHERS + END AS importer_node_id, + CASE + WHEN f_7.node_type_name = 'COUNTRY' THEN f_7.node_id -- BRAZIL-SOY + WHEN f_4.node_type_name = 'COUNTRY' THEN f_4.node_id -- BRAZIL-BEEF + WHEN f_3.node_type_name = 'COUNTRY' THEN f_3.node_id -- OTHERS + END AS country_node_id, + fi.attribute_type, + fi.attribute_id, + fi.name AS attribute_name, + fi.name_with_unit AS attribute_name_with_unit, + fi.display_name, + STRING_AGG(fi.text_value, ' / ') AS text_values, + SUM(fi.numeric_value) AS sum, + CASE + WHEN fi.attribute_type = 'Qual' THEN STRING_AGG(fi.text_value, ' / ') + ELSE SUM(fi.numeric_value)::TEXT + END AS total +FROM flow_paths_mv f_0 +JOIN flow_paths_mv f_1 ON f_1.flow_id = f_0.flow_id AND f_1.column_position = 1 +JOIN flow_paths_mv f_2 ON f_2.flow_id = f_0.flow_id AND f_2.column_position = 2 +JOIN flow_paths_mv f_3 ON f_3.flow_id = f_0.flow_id AND f_3.column_position = 3 +LEFT JOIN flow_paths_mv f_4 ON f_4.flow_id = f_0.flow_id AND f_4.column_position = 4 +LEFT JOIN flow_paths_mv f_5 ON f_5.flow_id = f_0.flow_id AND f_5.column_position = 5 +LEFT JOIN flow_paths_mv f_6 ON f_6.flow_id = f_0.flow_id AND f_6.column_position = 6 +LEFT JOIN flow_paths_mv f_7 ON f_7.flow_id = f_0.flow_id AND f_7.column_position = 7 +JOIN ( + SELECT + f.flow_id, f.qual_id AS attribute_id, 'Qual' AS attribute_type, + null AS numeric_value, + value AS text_value, + q.name, + null AS unit, + q.name AS name_with_unit, + da.display_name, + da.context_id + FROM flow_quals f + JOIN quals q ON f.qual_id = q.id + JOIN download_quals dq ON dq.qual_id = q.id + JOIN download_attributes da ON dq.download_attribute_id = da.id + GROUP BY f.flow_id, f.qual_id, f.value, q.name, da.display_name, da.context_id + + UNION ALL + + SELECT + f.flow_id, f.quant_id, 'Quant', + f.value, + null, + q.name, + q.unit, + CASE + WHEN unit IS null THEN q.name + ELSE q.name || ' (' || q.unit || ')' + END, + da.display_name, + da.context_id + FROM flow_quants f + JOIN quants q ON f.quant_id = q.id + JOIN download_quants dq ON dq.quant_id = q.id + JOIN download_attributes da ON dq.download_attribute_id = da.id + GROUP BY f.flow_id, f.quant_id, f.value, q.name, q.unit, da.display_name, da.context_id +) fi ON f_0.flow_id = fi.flow_id AND f_0.context_id = fi.context_id +WHERE f_0.column_position = 0 +GROUP BY + f_0.flow_id, + f_0.context_id, + f_0.year, + f_0.name, + f_0.node_id, + f_1.name, + f_1.node_id, + f_1.node_type_name, + f_2.name, + f_2.node_id, + f_2.node_type_name, + f_3.name, + f_3.node_id, + f_3.node_type_name, + f_4.name, + f_4.node_id, + f_4.node_type_name, + f_5.name, + f_5.node_id, + f_5.node_type_name, + f_6.name, + f_6.node_id, + f_6.node_type_name, + f_7.name, + f_7.node_id, + f_7.node_type_name, + fi.attribute_type, + fi.attribute_id, + fi.name, + fi.name_with_unit, + fi.display_name;