Skip to content

Commit

Permalink
#144 Handle null telemetry, move logic to function
Browse files Browse the repository at this point in the history
  • Loading branch information
1yuv committed Feb 9, 2024
1 parent 0c7573b commit e4d72f9
Show file tree
Hide file tree
Showing 7 changed files with 158 additions and 59 deletions.
43 changes: 20 additions & 23 deletions libs/medic-users-meta/migrations/202105171933.do.86.usersMeta.sql
Original file line number Diff line number Diff line change
Expand Up @@ -24,29 +24,26 @@ CREATE INDEX idx_useview_feedback_period_start_user ON useview_feedback(period_s
CREATE MATERIALIZED VIEW useview_telemetry AS
SELECT
doc->>'_id' AS uuid,
(CASE
WHEN doc#>>'{metadata,year}' IS NULL THEN '1970-1-1'
ELSE
CONCAT_WS( --> Date concatenation from JSON fields, eg. 2021-5-17
'-',
doc#>>'{metadata,year}', --> year
CASE --> month of the year
WHEN
string_to_array(substring(doc#>>'{metadata,versions,app}' FROM '(\d+.\d+.\d+)'),'.')::int[] < '{3,8,0}'::int[]
THEN
(doc#>>'{metadata,month}')::int+1 --> Legacy, months zero-indexed (0 - 11)
ELSE
(doc#>>'{metadata,month}')::int --> Month is between 1 - 12
END,
CASE --> day of the month, else 1
WHEN
(doc#>>'{metadata,day}') IS NOT NULL
THEN
doc#>>'{metadata,day}'
ELSE
'1'
END)
END)::date AS period_start,
CONCAT_WS( --> Date concatenation from JSON fields, eg. 2021-5-17
'-',
doc#>>'{metadata,year}', --> year
CASE --> month of the year
WHEN
string_to_array(substring(doc#>>'{metadata,versions,app}' FROM '(\d+.\d+.\d+)'),'.')::int[] < '{3,8,0}'::int[]
THEN
(doc#>>'{metadata,month}')::int+1 --> Legacy, months zero-indexed (0 - 11)
ELSE
(doc#>>'{metadata,month}')::int --> Month is between 1 - 12
END,
CASE --> day of the month, else 1
WHEN
(doc#>>'{metadata,day}') IS NOT NULL
THEN
doc#>>'{metadata,day}'
ELSE
'1'
END
)::date 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,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -9,28 +9,26 @@ SELECT
doc #>> '{_id}' AS telemetry_doc_id,
doc #>> '{metadata,deviceId}' AS device_id,
doc #>> '{metadata,user}' AS user_name,
(CASE
WHEN doc#>>'{metadata,year}' IS NULL THEN '1970-1-1'
ELSE
concat_ws(
'-',
doc #>> '{metadata,year}',
CASE
WHEN
doc #>> '{metadata,day}' IS NULL
AND (
doc #>> '{metadata,versions,app}' IS NULL
OR string_to_array("substring"(doc #>> '{metadata,versions,app}', '(\d+.\d+.\d+)'), '.')::integer[] < '{3,8,0}'::integer[]
)
THEN (doc #>> '{metadata,month}')::integer + 1
ELSE (doc #>> '{metadata,month}')::integer
END,
CASE
WHEN doc #>> '{metadata,day}' IS NOT NULL
THEN doc #>> '{metadata,day}'
ELSE '1'
END)
END)::date AS period_start,

concat_ws(
'-',
doc #>> '{metadata,year}',
CASE
WHEN
doc #>> '{metadata,day}' IS NULL
AND (
doc #>> '{metadata,versions,app}' IS NULL
OR string_to_array("substring"(doc #>> '{metadata,versions,app}', '(\d+.\d+.\d+)'), '.')::integer[] < '{3,8,0}'::integer[]
)
THEN (doc #>> '{metadata,month}')::integer + 1
ELSE (doc #>> '{metadata,month}')::integer
END,
CASE
WHEN doc #>> '{metadata,day}' IS NOT NULL
THEN doc #>> '{metadata,day}'
ELSE '1'
END
)::date AS period_start,


doc #>> '{device,deviceInfo,hardware,manufacturer}' AS device_manufacturer,
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -8,20 +8,17 @@ WITH telemetry_docs_with_metric_blob AS (
doc #>> '{metadata,deviceId}' AS device_id,
doc #>> '{_id}' AS telemetry_doc_id,
doc #>> '{metadata,user}' AS user_name,
(CASE
WHEN doc#>>'{metadata,year}' IS NULL THEN '1970-1-1'
ELSE
concat_ws(
'-', doc #>> '{metadata,year}',
CASE
WHEN (doc #>> '{metadata,day}') IS NULL AND ((doc #>> '{metadata,versions,app}') IS NULL OR string_to_array("substring"(doc #>> '{metadata,versions,app}', '(\d+.\d+.\d+)'::text), '.'::text)::integer[] < '{3,8,0}'::integer[]) THEN ((doc #>> '{metadata,month}')::integer) + 1
ELSE (doc #>> '{metadata,month}')::integer
END,
CASE
WHEN (doc #>> '{metadata,day}') IS NOT NULL THEN doc #>> '{metadata,day}'
ELSE '1'::text
END)
END)::date AS period_start,
concat_ws(
'-', doc #>> '{metadata,year}',
CASE
WHEN (doc #>> '{metadata,day}') IS NULL AND ((doc #>> '{metadata,versions,app}') IS NULL OR string_to_array("substring"(doc #>> '{metadata,versions,app}', '(\d+.\d+.\d+)'::text), '.'::text)::integer[] < '{3,8,0}'::integer[]) THEN ((doc #>> '{metadata,month}')::integer) + 1
ELSE (doc #>> '{metadata,month}')::integer
END,
CASE
WHEN (doc #>> '{metadata,day}') IS NOT NULL THEN doc #>> '{metadata,day}'
ELSE '1'::text
END
)::date 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
Expand Down
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;
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);
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);
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);

0 comments on commit e4d72f9

Please sign in to comment.