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..33b71bf --- /dev/null +++ b/assets/server-scripts/opensrp-client-anc_contact-visit-detailed-view.sql @@ -0,0 +1,149 @@ +-- 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 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 ( + 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' + $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-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 new file mode 100644 index 0000000..60e9d25 --- /dev/null +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb-nested.sql @@ -0,0 +1,56 @@ +-- 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; + 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, with nested json object(s) `identifiers` and `attributes` +SELECT + core.create_jsonb_nested_flat_view( + 'client', + 'id, date_deleted, server_version', + 'json', + 'identifiers', 'attributes' + ); 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..11a5bbb --- /dev/null +++ b/assets/server-scripts/opensrp-client-core_flatten-jsonb.sql @@ -0,0 +1,138 @@ +-- 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; + 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 $$; + +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 + $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 + 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 + $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(); 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'));