From 7acee189b2eb8ef79b6c23aabb3aba6dd639da96 Mon Sep 17 00:00:00 2001 From: Levi Date: Thu, 15 Sep 2022 12:26:19 +0700 Subject: [PATCH 1/7] Affected Issue(s): Add views for data analytics What this commit has achieved: 1. Created some functions to generate views 2. Inspired by https://stackoverflow.com/a/35179515, https://stackoverflow.com/a/54290549, and the motivation to do so by https://ellisvalentiner.com/post/2022-01-06-flattening-json-in-postgres/ 3. TODO maybe add these scripts into the MyBatis migrations --- ...client-anc_contact-visit-detailed-view.sql | 146 +++++++++++++++++ .../opensrp-client-core_flatten-jsonb.sql | 153 ++++++++++++++++++ 2 files changed, 299 insertions(+) create mode 100644 assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql create mode 100644 assets/server-scripts/opensrp-client-core_flatten-jsonb.sql diff --git a/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql b/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql new file mode 100644 index 0000000..13999d9 --- /dev/null +++ b/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql @@ -0,0 +1,146 @@ +-- OpenSRP Client ANC Core Event create "Contact Visit" detailed view func +create or replace function core.create_core_event_contact_visit_jsonb_flat_view() + returns text language plpgsql as $$ +declare + cols text; + previous_contacts_cols TEXT; + attention_flag_facts_cols TEXT; + open_test_tasks_flat_array_cols TEXT; +begin + execute format ($ex$ + select string_agg(format('e."json"->>%%1$L "%%1$s"', key), ', ') + from ( + select distinct key + from core."event" e, jsonb_each(e."json") + WHERE e."json" ->> 'eventType' = 'Contact Visit' + order by 1 + ) s; + $ex$) + into cols; + execute format ($ex$ + select string_agg(format('jsonb_pc."prev_cntcts"->>%%1$L "prev_cntcts.%%1$s"', key), ', ') + from ( + select distinct key + from core."event" e, + jsonb_to_record(e."json" -> 'details') AS details( + "previous_contacts" text + ), + jsonb_each(details."previous_contacts"::jsonb) + WHERE e."json" ->> 'eventType' = 'Contact Visit' + order by 1 + ) s; + $ex$) + into previous_contacts_cols; + execute format ($ex$ + select string_agg(format('jsonb_aff."attention_f_facts"->>%%1$L "attention_f_facts.%%1$s"', key), ', ') + from ( + select distinct key + from core."event" e, + jsonb_to_record(e."json" -> 'details') AS details( + "attention_flag_facts" text + ), + jsonb_each(details."attention_flag_facts"::jsonb) + WHERE e."json" ->> 'eventType' = 'Contact Visit' + order by 1 + ) s; + $ex$) + into attention_flag_facts_cols; + execute format ($ex$ + select string_agg(format('e_sub.open_test_tasks_flat_array->>%%1$L "%%1$s"', key), ', ') + from ( + select distinct key + from core."event" e, + jsonb_to_record(e."json" -> 'details') AS details( + "open_test_tasks" text + ), + jsonb_each( + core.flat_array( + ( + '{"open_t_tasks": ' || + REPLACE( + REPLACE( + REPLACE( + details."open_test_tasks", + '"{', + '{' + ), + '}"', + '}' + ), + '\"', + '"' + ) + || '}' + )::jsonb, + 'open_t_tasks', + 'key' + ) + ) + WHERE e."json" ->> 'eventType' = 'Contact Visit' + order by 1 + ) s; + $ex$) + into open_test_tasks_flat_array_cols; + execute format($ex$ + drop view if exists core."event_Contact Visit detailed_view"; + create view core."event_Contact Visit detailed_view" as + select e.id, date_deleted, server_version, + %1$s, + details."Contact", + details."form_submission_ids", + %2$s, + %3$s, + %4$s + from core."event" e + LEFT JOIN ( + SELECT + e2.id "id", + core.flat_array( + ( + '{"open_t_tasks": ' || + REPLACE( + REPLACE( + REPLACE( + details2."open_test_tasks", + '"{', + '{' + ), + '}"', + '}' + ), + '\"', + '"' + ) + || '}' + )::jsonb, + 'open_t_tasks', + 'key' + ) AS open_test_tasks_flat_array + FROM + core."event" e2, + jsonb_to_record(e2."json" -> 'details') AS details2( + "open_test_tasks" text + ) + WHERE + e2."json" ->> 'eventType' = 'Contact Visit' + ) e_sub ON e_sub.id = e.id + CROSS JOIN jsonb_to_record(e."json" -> 'details') AS details( + "Contact" TEXT, + "form_submission_ids" TEXT, + "previous_contacts" TEXT, + "attention_flag_facts" TEXT + ) + CROSS JOIN + jsonb_to_record(('{"attention_f_facts":' || details."attention_flag_facts" || '}')::jsonb + ) AS jsonb_aff("attention_f_facts" jsonb) + CROSS JOIN + jsonb_to_record(('{"prev_cntcts":' || details."previous_contacts" || '}')::jsonb + ) AS jsonb_pc("prev_cntcts" jsonb) + WHERE e."json" ->> 'eventType' = 'Contact Visit' + ORDER BY e.id + $ex$, cols, previous_contacts_cols, attention_flag_facts_cols, open_test_tasks_flat_array_cols); + return cols || previous_contacts_cols || attention_flag_facts_cols || open_test_tasks_flat_array_cols; +end $$; + +SELECT + core.create_core_event_contact_visit_jsonb_flat_view(); diff --git a/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql b/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql new file mode 100644 index 0000000..62549a1 --- /dev/null +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql @@ -0,0 +1,153 @@ +-- Specific logic hidden in the arrays https://stackoverflow.com/a/54290549 +create or replace function core.flat_array(data jsonb, title text, item text) +returns jsonb language sql immutable as $$ + select jsonb_object_agg(format('%s.%s.%s', title, elem->>item, key), value) + from jsonb_array_elements(data->title) as arr(elem) + cross join jsonb_each(elem) + where key <> item +$$; + + + +-- Generalized solution (for jsonb) https://stackoverflow.com/a/35179515 +create or replace function core.create_jsonb_flat_view + (table_name text, regular_columns text, json_column text) + returns text language plpgsql as $$ +declare + cols text; +begin + execute format ($ex$ + select string_agg(format('%2$s->>%%1$L "%%1$s"', key), ', ') + from ( + select distinct key + from core.%1$s, jsonb_each(%2$s) + order by 1 + ) s; + $ex$, table_name, json_column) + into cols; + IF (table_name = 'event') THEN + execute format($ex$ + drop view if exists core.%1$s_view; + create view core.%1$s_view as + select %2$s, %3$s from core.%1$s e + ORDER BY e.%4$s ->> 'eventType', e.%4$s ->> 'providerId', e.id + $ex$, table_name, regular_columns, cols, json_column); + ELSIF (table_name = 'client') THEN + execute format($ex$ + drop view if exists core.%1$s_view; + create view core.%1$s_view as + select %2$s, %3$s from core.%1$s c + ORDER BY c.%4$s ->> 'firstName', c.id + $ex$, table_name, regular_columns, cols, json_column); + ELSE + execute format($ex$ + drop view if exists core.%1$s_view; + create view core.%1$s_view as + select %2$s, %3$s from core.%1$s a + ORDER BY a.id + $ex$, table_name, regular_columns, cols); + END IF; + return cols; +end $$; + +SELECT + core.create_jsonb_flat_view('client', + 'id, date_deleted, server_version', + 'json'), + core.create_jsonb_flat_view('event', + 'id, date_deleted, server_version', + 'json'); + + + +-- OpenSRP Core Event create view func +create or replace function core.create_core_event_jsonb_flat_view + (table_name text, regular_columns text, json_column text, event_type text) + returns text language plpgsql as $$ +declare + cols text; + flat_obs_cols text; +begin + execute format ($ex$ + select string_agg(format('%2$s->>%%1$L "%%1$s"', key), ', ') + from ( + select distinct key + from core.%1$s e, jsonb_each(%2$s) + WHERE e.%2$s ->> 'eventType' = %3$L + order by 1 + ) s; + $ex$, table_name, json_column, event_type) + into cols; + execute format ($ex$ + select string_agg(format('e_sub.obs_flat_array->>%%1$L "%%1$s"', key), ', ') + from ( + select distinct key + from core.%1$s e, jsonb_each(core.flat_array(e.%2$s, + 'obs', + 'formSubmissionField')) + WHERE e.%2$s ->> 'eventType' = %3$L + order by 1 + ) s; + $ex$, table_name, json_column, event_type) + into flat_obs_cols; + IF flat_obs_cols IS NULL THEN + execute format($ex$ + drop view if exists core."%1$s_%5$s_view"; + create view core."%1$s_%5$s_view" as + select %2$s, %3$s from core.%1$s e + WHERE e.%4$s ->> 'eventType' = %5$L + ORDER BY e.id + $ex$, table_name, regular_columns, cols, json_column, event_type); + ELSE + execute format($ex$ + drop view if exists core."%1$s_%5$s_view"; + create view core."%1$s_%5$s_view" as + select %2$s, %3$s, %6$s from core.%1$s e + LEFT JOIN (SELECT + e2.id, + core.flat_array(e2.%4$s, + 'obs', + 'formSubmissionField') AS obs_flat_array + FROM + core.%1$s e2 + WHERE + e2.%4$s ->> 'eventType' = %5$L) e_sub ON e_sub.id = e.id + WHERE e.%4$s ->> 'eventType' = %5$L + ORDER BY e.id + $ex$, table_name, regular_columns, cols, json_column, event_type, flat_obs_cols); + END IF; + return cols || flat_obs_cols; +end $$; + + + +-- OpenSRP Core Event generate all event type views +create or replace function core.generate_all_event_type_views() + returns text language plpgsql as $$ +declare + the_queries text; +begin + execute format ($ex$ + select + string_agg( + format('core.create_core_event_jsonb_flat_view(''event'',''e.id, date_deleted, server_version'',''json'',%%1$L)', "eventType"), + ', ' + ) + from ( + SELECT + DISTINCT e."json" ->> 'eventType' AS "eventType" + FROM + core."event" e + ORDER BY + 1 + ) s; + $ex$) + into the_queries; + execute format($ex$ + select %1$s + $ex$, the_queries); + return the_queries; +end $$; + +SELECT + core.generate_all_event_type_views(); From b01845d8b3b4cc3ebe9afaac7b7f92450f10f064 Mon Sep 17 00:00:00 2001 From: Levi Date: Thu, 15 Sep 2022 17:22:32 +0700 Subject: [PATCH 2/7] Affected Issue(s): Add views for data analytics What this commit has achieved: 1. Add `client_detailed_view` for OpenSRP-Client-ANC --- ...pensrp-client-anc_client-detailed-view.sql | 51 +++++++++++++++++++ 1 file changed, 51 insertions(+) create mode 100644 assets/server-scripts/opensrp-client-anc_client-detailed-view.sql diff --git a/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql b/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql new file mode 100644 index 0000000..558ff58 --- /dev/null +++ b/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql @@ -0,0 +1,51 @@ +-- OpenSRP Client ANC Core Client create client detailed view func +create or replace function core.create_core_client_anc_jsonb_flat_view() + returns text language plpgsql as $$ +declare + cols text; + attributes_cols text; + identifiers_cols text; + final_selected_cols TEXT; +begin + execute format ($ex$ + select string_agg(format('c."json"->>%%1$L "%%1$s"', key), ', ') + from ( + select distinct key + from core."client" c, jsonb_each(c."json") + order by 1 + ) s; + $ex$) + into cols; + execute format ($ex$ + select string_agg(format('c."json"->''attributes''->>%%1$L "attributes.%%1$s"', key), ', ') + from ( + select distinct key + from core."client" c, jsonb_each(c."json" -> 'attributes') + order by 1 + ) s; + $ex$) + into attributes_cols; + execute format ($ex$ + select string_agg(format('c."json"->''identifiers''->>%%1$L "identifiers.%%1$s"', key), ', ') + from ( + select distinct key + from core."client" c, jsonb_each(c."json" -> 'identifiers') + order by 1 + ) s; + $ex$) + into identifiers_cols; + SELECT concat_ws(', ', cols, identifiers_cols, attributes_cols) + INTO final_selected_cols; + execute format($ex$ + drop view if exists core."client_detailed_view"; + create view core."client_detailed_view" as + select c.id, date_deleted, server_version, + %1$s + from core."client" c + ORDER BY c."json" ->> 'firstName', c."json" -> 'identifiers' ->> 'ANC_ID', c.id + $ex$, final_selected_cols); + return final_selected_cols; +end $$; + +SELECT + core.create_core_client_anc_jsonb_flat_view(); From 4b2575f651f626b51f16f751d82731846072896a Mon Sep 17 00:00:00 2001 From: Levi Date: Tue, 20 Sep 2022 13:54:17 +0700 Subject: [PATCH 3/7] Affected Issue(s): `jsonb` nested object(s) What this commit has achieved: 1. Created a function to create jsonb flat view with capability of flattening nested object(s) --- ...ensrp-client-core_flatten-jsonb-nested.sql | 81 +++++++++++++++++++ 1 file changed, 81 insertions(+) create mode 100644 assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql diff --git a/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql b/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql new file mode 100644 index 0000000..41e1f41 --- /dev/null +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql @@ -0,0 +1,81 @@ +-- Generalized solution (for jsonb) https://stackoverflow.com/a/35179515 +create or replace function core.create_jsonb_nested_flat_view + (table_name text, regular_columns text, json_column TEXT, VARIADIC json_nested_columns TEXT[] DEFAULT '{}') + returns text language plpgsql as $$ +declare + cols text; + nested_cols TEXT; + nested_col TEXT; + temp_nested_cols text; + final_selected_cols TEXT; +begin + execute format ($ex$ + select string_agg(format('%2$s->>%%1$L "%%1$s"', key), ', ') + from ( + select distinct key + from core.%1$s, jsonb_each(%2$s) + order by 1 + ) s; + $ex$, table_name, json_column) + into cols; + FOREACH nested_col IN ARRAY json_nested_columns + LOOP + execute format ($ex$ + select string_agg(format('%2$s -> ''%3$s'' ->> %%1$L "%3$s.%%1$s"', key), ', ') + from ( + select distinct key + from core.%1$s, jsonb_each(%2$s -> %3$L) + order by 1 + ) s; + $ex$, table_name, json_column, nested_col) + into temp_nested_cols; + SELECT concat_ws(', ', nested_cols, temp_nested_cols) + INTO nested_cols; + execute format ($ex$ + SELECT REPLACE(%3$L, ', %2$s->>''%1$s'' "%1$s"', '') + $ex$, nested_col, json_column, cols) + INTO cols; + END LOOP; + SELECT concat_ws(', ', cols, nested_cols) + INTO final_selected_cols; + IF (table_name = 'event') THEN + execute format($ex$ + drop view if exists core.%1$s_detailed_view; + create view core.%1$s_detailed_view as + select %2$s, %3$s from core.%1$s e + ORDER BY e.%4$s ->> 'eventType', e.%4$s ->> 'providerId', e.id + $ex$, table_name, regular_columns, final_selected_cols, json_column); + ELSIF (table_name = 'client') THEN + execute format($ex$ + drop view if exists core.%1$s_detailed_view; + create view core.%1$s_detailed_view as + select %2$s, %3$s from core.%1$s c + ORDER BY c.%4$s ->> 'firstName', c.id + $ex$, table_name, regular_columns, final_selected_cols, json_column); + ELSE + execute format($ex$ + drop view if exists core.%1$s_detailed_view; + create view core.%1$s_detailed_view as + select %2$s, %3$s from core.%1$s a + ORDER BY a.id + $ex$, table_name, regular_columns, final_selected_cols); + END IF; + return final_selected_cols; +end $$; + +-- Sample usage, without nested json object(s) +SELECT + core.create_jsonb_nested_flat_view( + 'client', + 'id, date_deleted, server_version', + 'json' + ); + +-- Sample usage, with nested json object(s) +SELECT + core.create_jsonb_nested_flat_view( + 'client', + 'id, date_deleted, server_version', + 'json', + 'attributes', 'identifiers' + ); From a5167ff74bb23f5b5ce7c1a03ed64a826d0d449a Mon Sep 17 00:00:00 2001 From: Levi Date: Tue, 20 Sep 2022 14:41:38 +0700 Subject: [PATCH 4/7] Affected Issue(s): `jsonb` nested object(s) What this commit has achieved: 1. Reorder the nested column names 2. Deselect root property `obs`, as the flat array already selected --- .../opensrp-client-core_flatten-jsonb-nested.sql | 2 +- assets/server-scripts/opensrp-client-core_flatten-jsonb.sql | 4 ++++ 2 files changed, 5 insertions(+), 1 deletion(-) diff --git a/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql b/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql index 41e1f41..2fc12a3 100644 --- a/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql @@ -77,5 +77,5 @@ SELECT 'client', 'id, date_deleted, server_version', 'json', - 'attributes', 'identifiers' + 'identifiers', 'attributes' ); diff --git a/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql b/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql index 62549a1..95749e5 100644 --- a/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql @@ -99,6 +99,10 @@ begin ORDER BY e.id $ex$, table_name, regular_columns, cols, json_column, event_type); ELSE + execute format ($ex$ + SELECT REPLACE(%1$L, ', %2$s->>''obs'' "obs"', '') -- deselect 'obs' col + $ex$, cols, json_column) + INTO cols; execute format($ex$ drop view if exists core."%1$s_%5$s_view"; create view core."%1$s_%5$s_view" as From 2fb8fc680ec39a90a6f09854f56eac3935b729ab Mon Sep 17 00:00:00 2001 From: Levi Date: Tue, 20 Sep 2022 17:07:56 +0700 Subject: [PATCH 5/7] Affected Issue(s): OpenSRP Client ANC, event "Contact Visit" What this commit has achieved: 1. Deselect column `e."json"->>'details' "details"` because flattened already. --- .../opensrp-client-anc_contact-visit-detailed-view.sql | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql b/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql index 13999d9..4da1c2e 100644 --- a/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql +++ b/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql @@ -17,6 +17,10 @@ begin ) s; $ex$) into cols; + execute format ($ex$ + SELECT REPLACE(%1$L, ', e."json"->>''details'' "details"', '') -- deselect 'details' col + $ex$, cols) + INTO cols; execute format ($ex$ select string_agg(format('jsonb_pc."prev_cntcts"->>%%1$L "prev_cntcts.%%1$s"', key), ', ') from ( From 7ac287b7f0620ad81a245a02771ceef52f29ae98 Mon Sep 17 00:00:00 2001 From: Levi Date: Tue, 8 Nov 2022 15:41:46 +0700 Subject: [PATCH 6/7] Affected Issue(s): Automate views generation (cron) https://www.notion.so/sid-levi/SysAdmin-Automate-generate_all_event_type_views-of-Bunda-App-data-0db0372bcb824c5595f2780f85202da3 What this commit has achieved: 1. Removed all "ORDER BY" in the view, let user to order lastly 2. Created indexes to optimize the query plan --- ...pensrp-client-anc_client-detailed-view.sql | 1 - ...client-anc_contact-visit-detailed-view.sql | 1 - .../opensrp-client-anc_refresh_all_views.sql | 6 +++ ...ensrp-client-core_flatten-jsonb-nested.sql | 37 +++---------------- .../opensrp-client-core_flatten-jsonb.sql | 29 +++------------ .../server-scripts/opensrp-create-indexes.sql | 5 +++ 6 files changed, 22 insertions(+), 57 deletions(-) create mode 100644 assets/server-scripts/opensrp-client-anc_refresh_all_views.sql create mode 100644 assets/server-scripts/opensrp-create-indexes.sql diff --git a/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql b/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql index 558ff58..5578f77 100644 --- a/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql +++ b/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql @@ -42,7 +42,6 @@ begin select c.id, date_deleted, server_version, %1$s from core."client" c - ORDER BY c."json" ->> 'firstName', c."json" -> 'identifiers' ->> 'ANC_ID', c.id $ex$, final_selected_cols); return final_selected_cols; end $$; diff --git a/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql b/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql index 4da1c2e..33b71bf 100644 --- a/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql +++ b/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql @@ -141,7 +141,6 @@ begin jsonb_to_record(('{"prev_cntcts":' || details."previous_contacts" || '}')::jsonb ) AS jsonb_pc("prev_cntcts" jsonb) WHERE e."json" ->> 'eventType' = 'Contact Visit' - ORDER BY e.id $ex$, cols, previous_contacts_cols, attention_flag_facts_cols, open_test_tasks_flat_array_cols); return cols || previous_contacts_cols || attention_flag_facts_cols || open_test_tasks_flat_array_cols; end $$; diff --git a/assets/server-scripts/opensrp-client-anc_refresh_all_views.sql b/assets/server-scripts/opensrp-client-anc_refresh_all_views.sql new file mode 100644 index 0000000..a5377ba --- /dev/null +++ b/assets/server-scripts/opensrp-client-anc_refresh_all_views.sql @@ -0,0 +1,6 @@ +SELECT + core.generate_all_event_type_views(), + core.create_jsonb_flat_view('client', 'id, date_deleted, server_version', 'json'), + core.create_jsonb_flat_view('event', 'id, date_deleted, server_version', 'json'), + core.create_jsonb_nested_flat_view('client', 'id, date_deleted, server_version', 'json', 'identifiers', 'attributes'), + core.create_core_event_contact_visit_jsonb_flat_view(); \ No newline at end of file diff --git a/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql b/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql index 2fc12a3..60e9d25 100644 --- a/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql @@ -38,40 +38,15 @@ begin END LOOP; SELECT concat_ws(', ', cols, nested_cols) INTO final_selected_cols; - IF (table_name = 'event') THEN - execute format($ex$ - drop view if exists core.%1$s_detailed_view; - create view core.%1$s_detailed_view as - select %2$s, %3$s from core.%1$s e - ORDER BY e.%4$s ->> 'eventType', e.%4$s ->> 'providerId', e.id - $ex$, table_name, regular_columns, final_selected_cols, json_column); - ELSIF (table_name = 'client') THEN - execute format($ex$ - drop view if exists core.%1$s_detailed_view; - create view core.%1$s_detailed_view as - select %2$s, %3$s from core.%1$s c - ORDER BY c.%4$s ->> 'firstName', c.id - $ex$, table_name, regular_columns, final_selected_cols, json_column); - ELSE - execute format($ex$ - drop view if exists core.%1$s_detailed_view; - create view core.%1$s_detailed_view as - select %2$s, %3$s from core.%1$s a - ORDER BY a.id - $ex$, table_name, regular_columns, final_selected_cols); - END IF; + execute format($ex$ + drop view if exists core.%1$s_detailed_view; + create view core.%1$s_detailed_view as + select %2$s, %3$s from core.%1$s a + $ex$, table_name, regular_columns, final_selected_cols); return final_selected_cols; end $$; --- Sample usage, without nested json object(s) -SELECT - core.create_jsonb_nested_flat_view( - 'client', - 'id, date_deleted, server_version', - 'json' - ); - --- Sample usage, with nested json object(s) +-- Sample usage, with nested json object(s) `identifiers` and `attributes` SELECT core.create_jsonb_nested_flat_view( 'client', diff --git a/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql b/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql index 95749e5..11a5bbb 100644 --- a/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql @@ -25,28 +25,11 @@ begin ) s; $ex$, table_name, json_column) into cols; - IF (table_name = 'event') THEN - execute format($ex$ - drop view if exists core.%1$s_view; - create view core.%1$s_view as - select %2$s, %3$s from core.%1$s e - ORDER BY e.%4$s ->> 'eventType', e.%4$s ->> 'providerId', e.id - $ex$, table_name, regular_columns, cols, json_column); - ELSIF (table_name = 'client') THEN - execute format($ex$ - drop view if exists core.%1$s_view; - create view core.%1$s_view as - select %2$s, %3$s from core.%1$s c - ORDER BY c.%4$s ->> 'firstName', c.id - $ex$, table_name, regular_columns, cols, json_column); - ELSE - execute format($ex$ - drop view if exists core.%1$s_view; - create view core.%1$s_view as - select %2$s, %3$s from core.%1$s a - ORDER BY a.id - $ex$, table_name, regular_columns, cols); - END IF; + execute format($ex$ + drop view if exists core.%1$s_view; + create view core.%1$s_view as + select %2$s, %3$s from core.%1$s a + $ex$, table_name, regular_columns, cols); return cols; end $$; @@ -96,7 +79,6 @@ begin create view core."%1$s_%5$s_view" as select %2$s, %3$s from core.%1$s e WHERE e.%4$s ->> 'eventType' = %5$L - ORDER BY e.id $ex$, table_name, regular_columns, cols, json_column, event_type); ELSE execute format ($ex$ @@ -117,7 +99,6 @@ begin WHERE e2.%4$s ->> 'eventType' = %5$L) e_sub ON e_sub.id = e.id WHERE e.%4$s ->> 'eventType' = %5$L - ORDER BY e.id $ex$, table_name, regular_columns, cols, json_column, event_type, flat_obs_cols); END IF; return cols || flat_obs_cols; diff --git a/assets/server-scripts/opensrp-create-indexes.sql b/assets/server-scripts/opensrp-create-indexes.sql new file mode 100644 index 0000000..65516f1 --- /dev/null +++ b/assets/server-scripts/opensrp-create-indexes.sql @@ -0,0 +1,5 @@ +CREATE INDEX "client_json_baseEntityId_idx" ON core.client (("json" ->> 'baseEntityId')); + +CREATE INDEX "event_json_eventType_idx" ON core."event" (("json" ->> 'eventType')); + +CREATE INDEX "event_json_baseEntityId_idx" ON core."event" (("json" ->> 'baseEntityId')); From 47656fb9e8eb58a20173e8de13188e16edd53d1f Mon Sep 17 00:00:00 2001 From: Levi Date: Tue, 8 Nov 2022 15:49:53 +0700 Subject: [PATCH 7/7] Affected Issue(s): Remove unused script https://www.notion.so/sid-levi/SysAdmin-Automate-generate_all_event_type_views-of-Bunda-App-data-0db0372bcb824c5595f2780f85202da3 What this commit has achieved: 1. Removed `opensrp-client-anc_client-detailed-view.sql` 2. Can use `create_jsonb_nested_flat_view` function to achieve the same ``` core.create_jsonb_nested_flat_view( 'client', 'id, date_deleted, server_version', 'json', 'identifiers', 'attributes' ); ``` --- ...pensrp-client-anc_client-detailed-view.sql | 50 ------------------- 1 file changed, 50 deletions(-) delete mode 100644 assets/server-scripts/opensrp-client-anc_client-detailed-view.sql diff --git a/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql b/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql deleted file mode 100644 index 5578f77..0000000 --- a/assets/server-scripts/opensrp-client-anc_client-detailed-view.sql +++ /dev/null @@ -1,50 +0,0 @@ --- OpenSRP Client ANC Core Client create client detailed view func -create or replace function core.create_core_client_anc_jsonb_flat_view() - returns text language plpgsql as $$ -declare - cols text; - attributes_cols text; - identifiers_cols text; - final_selected_cols TEXT; -begin - execute format ($ex$ - select string_agg(format('c."json"->>%%1$L "%%1$s"', key), ', ') - from ( - select distinct key - from core."client" c, jsonb_each(c."json") - order by 1 - ) s; - $ex$) - into cols; - execute format ($ex$ - select string_agg(format('c."json"->''attributes''->>%%1$L "attributes.%%1$s"', key), ', ') - from ( - select distinct key - from core."client" c, jsonb_each(c."json" -> 'attributes') - order by 1 - ) s; - $ex$) - into attributes_cols; - execute format ($ex$ - select string_agg(format('c."json"->''identifiers''->>%%1$L "identifiers.%%1$s"', key), ', ') - from ( - select distinct key - from core."client" c, jsonb_each(c."json" -> 'identifiers') - order by 1 - ) s; - $ex$) - into identifiers_cols; - SELECT concat_ws(', ', cols, identifiers_cols, attributes_cols) - INTO final_selected_cols; - execute format($ex$ - drop view if exists core."client_detailed_view"; - create view core."client_detailed_view" as - select c.id, date_deleted, server_version, - %1$s - from core."client" c - $ex$, final_selected_cols); - return final_selected_cols; -end $$; - -SELECT - core.create_core_client_anc_jsonb_flat_view();