-
-
Notifications
You must be signed in to change notification settings - Fork 8
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
#144 Handle null telemetry, move logic to function
- Loading branch information
Showing
7 changed files
with
158 additions
and
59 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
22 changes: 22 additions & 0 deletions
22
libs/medic-users-meta/migrations/202402081825.do.get_telemetry_date.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,22 @@ | ||
DROP FUNCTION IF EXISTS get_telemetry_date(TEXT,TEXT,TEXT,TEXT) CASCADE; | ||
CREATE OR REPLACE FUNCTION get_telemetry_date(app_version TEXT, YEAR TEXT, MONTH TEXT, DAY TEXT) RETURNS date | ||
AS $$ | ||
BEGIN | ||
RETURN ( | ||
CASE | ||
WHEN COALESCE(YEAR,'')='' THEN NULL | ||
ELSE | ||
CONCAT_WS( | ||
'-', | ||
YEAR, | ||
CASE | ||
WHEN COALESCE(DAY,'')='' AND (COALESCE(app_version,'') ='' OR string_to_array(substring(app_version, '(\d+.\d+.\d+)'), '.')::integer[] < '{3,8,0}'::integer[]) | ||
THEN (MONTH::int + 1)::text | ||
ELSE MONTH | ||
END, | ||
COALESCE(DAY,'1') | ||
)::date | ||
END | ||
); | ||
END; | ||
$$ LANGUAGE plpgsql IMMUTABLE; |
19 changes: 19 additions & 0 deletions
19
libs/medic-users-meta/migrations/202402081830.do.useview_telemetry.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,19 @@ | ||
DROP MATERIALIZED VIEW IF EXISTS useview_telemetry CASCADE; | ||
|
||
CREATE MATERIALIZED VIEW useview_telemetry AS | ||
SELECT | ||
doc->>'_id' AS uuid, | ||
get_telemetry_date(doc#>>'{metadata,versions,app}',doc#>>'{metadata,year}',doc#>>'{metadata,month}',doc#>>'{metadata,day}') AS period_start, | ||
doc#>>'{metadata,user}' AS user_name, | ||
doc#>>'{metadata,versions,app}' AS app_version, | ||
doc#>>'{metrics,boot_time,min}' AS boot_time_min, | ||
doc#>>'{metrics,boot_time,max}' AS boot_time_max, | ||
doc#>>'{metrics,boot_time,count}' AS boot_time_count, | ||
doc#>>'{dbInfo,doc_count}' AS doc_count_on_local_db | ||
FROM | ||
couchdb_users_meta | ||
WHERE | ||
doc->>'type'='telemetry'; | ||
|
||
CREATE UNIQUE INDEX idx_useview_telemetry_uuid ON useview_telemetry(uuid); | ||
CREATE INDEX idx_useview_telemetry_period_start_user ON useview_telemetry(period_start,user_name); |
29 changes: 29 additions & 0 deletions
29
libs/medic-users-meta/migrations/202402183030.do.telemetry_devices.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,29 @@ | ||
DROP MATERIALIZED VIEW IF EXISTS useview_telemetry_devices CASCADE; | ||
|
||
CREATE MATERIALIZED VIEW public.useview_telemetry_devices | ||
TABLESPACE pg_default AS | ||
SELECT | ||
DISTINCT ON (doc #>> '{metadata,deviceId}', doc #>> '{metadata,user}') | ||
doc #>> '{_id}' AS telemetry_doc_id, | ||
doc #>> '{metadata,deviceId}' AS device_id, | ||
doc #>> '{metadata,user}' AS user_name, | ||
get_telemetry_date(doc#>>'{metadata,versions,app}',doc#>>'{metadata,year}',doc#>>'{metadata,month}',doc#>>'{metadata,day}') AS period_start, | ||
doc #>> '{device,deviceInfo,hardware,manufacturer}' AS device_manufacturer, | ||
doc #>> '{device,deviceInfo,hardware,model}' AS device_model, | ||
doc #>> '{dbInfo,doc_count}' AS doc_count, | ||
doc #>> '{device,userAgent}' AS user_agent, | ||
doc #>> '{device,deviceInfo,app,version}' AS cht_android_version, | ||
doc #>> '{device,deviceInfo,software,androidVersion}' AS android_version, | ||
doc #>> '{device,deviceInfo,storage,free}' AS storage_free, | ||
doc #>> '{device,deviceInfo,storage,total}' AS storage_total, | ||
doc #>> '{device,deviceInfo,network,upSpeed}' AS network_up_speed, | ||
doc #>> '{device,deviceInfo,network,downSpeed}' AS network_down_speed | ||
FROM | ||
couchdb_users_meta | ||
WHERE | ||
doc ->> 'type' = 'telemetry' | ||
ORDER BY | ||
2, 3, 4 ASC | ||
WITH DATA; | ||
|
||
CREATE UNIQUE INDEX useview_telemetry_devices_device_user ON public.useview_telemetry_devices USING btree (device_id, user_name); |
37 changes: 37 additions & 0 deletions
37
libs/medic-users-meta/migrations/202402183030.do.telemetry_metrics.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,37 @@ | ||
DROP MATERIALIZED VIEW IF EXISTS useview_telemetry_metrics CASCADE; | ||
|
||
CREATE MATERIALIZED VIEW public.useview_telemetry_metrics | ||
TABLESPACE pg_default AS | ||
WITH telemetry_docs_with_metric_blob AS ( | ||
SELECT | ||
doc #>> '{metadata,deviceId}' AS device_id, | ||
doc #>> '{_id}' AS telemetry_doc_id, | ||
doc #>> '{metadata,user}' AS user_name, | ||
get_telemetry_date(doc#>>'{metadata,versions,app}',doc#>>'{metadata,year}',doc#>>'{metadata,month}',doc#>>'{metadata,day}') AS period_start, | ||
jsonb_object_keys(doc -> 'metrics'::text) AS metric, | ||
doc -> 'metrics' -> jsonb_object_keys(doc -> 'metrics') AS metric_values | ||
FROM couchdb_users_meta | ||
WHERE doc ->> 'type' = 'telemetry' | ||
) | ||
SELECT | ||
telemetry_docs_with_metric_blob.telemetry_doc_id, | ||
telemetry_docs_with_metric_blob.metric, | ||
telemetry_docs_with_metric_blob.period_start, | ||
telemetry_docs_with_metric_blob.user_name, | ||
telemetry_docs_with_metric_blob.device_id, | ||
jsonb_to_record.min, | ||
jsonb_to_record.max, | ||
jsonb_to_record.sum, | ||
jsonb_to_record.count, | ||
jsonb_to_record.sumsqr | ||
FROM | ||
telemetry_docs_with_metric_blob | ||
CROSS JOIN LATERAL | ||
jsonb_to_record(telemetry_docs_with_metric_blob.metric_values) | ||
jsonb_to_record(min numeric, max numeric, sum numeric, count bigint, sumsqr numeric) | ||
WITH DATA; | ||
|
||
CREATE UNIQUE INDEX useview_telemetry_metrics_docid_metric ON public.useview_telemetry_metrics USING btree (telemetry_doc_id, metric); | ||
CREATE INDEX useview_telemetry_metrics_period_start ON public.useview_telemetry_metrics USING btree (period_start); | ||
CREATE INDEX useview_telemetry_metrics_device_id ON public.useview_telemetry_metrics USING btree (device_id); | ||
CREATE INDEX useview_telemetry_metrics_user_name ON public.useview_telemetry_metrics USING btree (user_name); |