Skip to content

Commit

Permalink
Create new aggregate table for Firefox Health Indicators dashboard (#…
Browse files Browse the repository at this point in the history
…6678)

* Create new aggregate table for Firefox Health Indicators dashboard

* Add aggregate table label and update table description

* Do not require partition filter
  • Loading branch information
kwindau authored Dec 16, 2024
1 parent ccf1963 commit cfd1a67
Show file tree
Hide file tree
Showing 4 changed files with 142 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
CREATE OR REPLACE VIEW
`moz-fx-data-shared-prod.telemetry.fx_health_ind_clients_daily_by_country`
AS
SELECT
*
FROM
`moz-fx-data-shared-prod.telemetry_derived.fx_health_ind_clients_daily_by_country_v1`
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
friendly_name: Fx Health Ind Clients Daily By Country
description: |-
Calculates active hrs, subsession hrs, and searches per user by country on a 1% client sample
owners:
- kwindau@mozilla.com
labels:
incremental: true
owner1: kwindau@mozilla.com
table_type: aggregate
scheduling:
dag_name: bqetl_fx_health_ind_dashboard
bigquery:
time_partitioning:
type: day
field: submission_date
require_partition_filter: false
expiration_days: null
range_partitioning: null
clustering:
fields:
- country
references: {}
Original file line number Diff line number Diff line change
@@ -0,0 +1,92 @@
WITH searches_per_user_by_country_and_date_staging AS (
SELECT
submission_date_s3,
country,
SUM(search_count_all) AS searches,
COUNT(DISTINCT client_id) AS users,
FROM
`moz-fx-data-shared-prod.telemetry.clients_daily`
WHERE
submission_date_s3 = @submission_date
AND app_name = 'Firefox'
AND sample_id = 42
AND search_count_all < 10000
GROUP BY
submission_date_s3,
country
),
searches_per_user_by_country_and_date AS (
SELECT
submission_date_s3,
country,
searches / users AS searches_per_user_ratio,
FROM
searches_per_user_by_country_and_date_staging
),
subsession_hours_per_user_staging AS (
SELECT
submission_date_s3,
country,
SUM(subsession_hours_sum) AS `hours`,
COUNT(DISTINCT client_id) AS users,
FROM
`moz-fx-data-shared-prod.telemetry.clients_daily`
WHERE
submission_date_s3 = @submission_date
AND app_name = 'Firefox'
AND sample_id = 42
AND subsession_hours_sum < 24
GROUP BY
submission_date_s3,
country
),
subsession_hours_per_user AS (
SELECT
submission_date_s3,
country,
`hours` / users AS subsession_hours_per_user_ratio
FROM
subsession_hours_per_user_staging
),
active_hours_per_user_staging AS (
SELECT
submission_date_s3,
country,
SUM(active_hours_sum) AS `hours`,
COUNT(DISTINCT(client_id)) AS users,
FROM
`moz-fx-data-shared-prod.telemetry.clients_daily`
WHERE
submission_date_s3 = @submission_date
AND app_name = 'Firefox'
AND sample_id = 42
AND active_hours_sum < 24
GROUP BY
submission_date_s3,
country
),
active_hours_per_user AS (
SELECT
submission_date_s3,
country,
`hours` / users AS active_hours_per_user_ratio
FROM
active_hours_per_user_staging
)
SELECT
COALESCE(
COALESCE(spu.submission_date_s3, sshpu.submission_date_s3),
ahpu.submission_date_s3
) AS submission_date,
COALESCE(COALESCE(spu.country, sshpu.country), ahpu.country) AS country,
spu.searches_per_user_ratio,
sshpu.subsession_hours_per_user_ratio,
ahpu.active_hours_per_user_ratio
FROM
searches_per_user_by_country_and_date AS spu
FULL OUTER JOIN
subsession_hours_per_user AS sshpu
ON spu.country = sshpu.country
FULL OUTER JOIN
active_hours_per_user AS ahpu
ON COALESCE(spu.country, sshpu.country) = ahpu.country
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
fields:
- mode: NULLABLE
name: submission_date
type: DATE
description: Submission Date
- mode: NULLABLE
name: country
type: STRING
description: Country
- mode: NULLABLE
name: searches_per_user_ratio
type: FLOAT
description: Ratio of Searches per User
- mode: NULLABLE
name: subsession_hours_per_user_ratio
type: NUMERIC
description: Ratio of Subsession Hours per User
- mode: NULLABLE
name: active_hours_per_user_ratio
type: FLOAT
description: Ratio of Active Hours per User

2 comments on commit cfd1a67

@dataops-ci-bot
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Integration report for "Create new aggregate table for Firefox Health Indicators dashboard (#6678)"

sql.diff

Click to expand!
diff -bur --no-dereference --new-file /tmp/workspace/main-generated-sql/dags/bqetl_fx_health_ind_dashboard.py /tmp/workspace/generated-sql/dags/bqetl_fx_health_ind_dashboard.py
--- /tmp/workspace/main-generated-sql/dags/bqetl_fx_health_ind_dashboard.py	2024-12-16 20:38:55.000000000 +0000
+++ /tmp/workspace/generated-sql/dags/bqetl_fx_health_ind_dashboard.py	2024-12-16 20:39:30.000000000 +0000
@@ -183,6 +183,17 @@
         pool="DATA_ENG_EXTERNALTASKSENSOR",
     )
 
+    telemetry_derived__fx_health_ind_clients_daily_by_country__v1 = bigquery_etl_query(
+        task_id="telemetry_derived__fx_health_ind_clients_daily_by_country__v1",
+        destination_table="fx_health_ind_clients_daily_by_country_v1",
+        dataset_id="telemetry_derived",
+        project_id="moz-fx-data-shared-prod",
+        owner="kwindau@mozilla.com",
+        email=["kwindau@mozilla.com", "telemetry-alerts@mozilla.com"],
+        date_partition_parameter="submission_date",
+        depends_on_past=False,
+    )
+
     telemetry_derived__fx_health_ind_clients_daily_by_os__v1 = bigquery_etl_query(
         task_id="telemetry_derived__fx_health_ind_clients_daily_by_os__v1",
         destination_table="fx_health_ind_clients_daily_by_os_v1",
@@ -278,6 +289,10 @@
         parameters=["submission_date:DATE:{{macros.ds_add(ds, -1)}}"],
     )
 
+    telemetry_derived__fx_health_ind_clients_daily_by_country__v1.set_upstream(
+        wait_for_telemetry_derived__clients_daily_joined__v1
+    )
+
     telemetry_derived__fx_health_ind_clients_daily_by_os__v1.set_upstream(
         wait_for_telemetry_derived__clients_daily_joined__v1
     )
Only in /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry: fx_health_ind_clients_daily_by_country
Only in /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived: fx_health_ind_clients_daily_by_country_v1
diff -bur --no-dereference --new-file /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/metadata.yaml /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/metadata.yaml
--- /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/metadata.yaml	1970-01-01 00:00:00.000000000 +0000
+++ /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/metadata.yaml	2024-12-16 20:35:02.000000000 +0000
@@ -0,0 +1,14 @@
+friendly_name: Fx Health Ind Clients Daily By Country
+description: |-
+  Please provide a description for the query
+owners: []
+labels: {}
+bigquery: null
+workgroup_access:
+- role: roles/bigquery.dataViewer
+  members:
+  - workgroup:dataops-managed/taar
+  - workgroup:mozilla-confidential
+references:
+  view.sql:
+  - moz-fx-data-shared-prod.telemetry_derived.fx_health_ind_clients_daily_by_country_v1
diff -bur --no-dereference --new-file /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/view.sql /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/view.sql
--- /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/view.sql	1970-01-01 00:00:00.000000000 +0000
+++ /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry/fx_health_ind_clients_daily_by_country/view.sql	2024-12-16 20:32:59.000000000 +0000
@@ -0,0 +1,7 @@
+CREATE OR REPLACE VIEW
+  `moz-fx-data-shared-prod.telemetry.fx_health_ind_clients_daily_by_country`
+AS
+SELECT
+  *
+FROM
+  `moz-fx-data-shared-prod.telemetry_derived.fx_health_ind_clients_daily_by_country_v1`
diff -bur --no-dereference --new-file /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/metadata.yaml /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/metadata.yaml
--- /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/metadata.yaml	1970-01-01 00:00:00.000000000 +0000
+++ /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/metadata.yaml	2024-12-16 20:35:03.000000000 +0000
@@ -0,0 +1,27 @@
+friendly_name: Fx Health Ind Clients Daily By Country
+description: |-
+  Calculates active hrs, subsession hrs, and searches per user by country on a 1% client sample
+owners:
+- kwindau@mozilla.com
+labels:
+  incremental: true
+  owner1: kwindau
+  table_type: aggregate
+  dag: bqetl_fx_health_ind_dashboard
+scheduling:
+  dag_name: bqetl_fx_health_ind_dashboard
+bigquery:
+  time_partitioning:
+    type: day
+    field: submission_date
+    require_partition_filter: false
+    expiration_days: null
+  range_partitioning: null
+  clustering:
+    fields:
+    - country
+workgroup_access:
+- role: roles/bigquery.dataViewer
+  members:
+  - workgroup:mozilla-confidential
+references: {}
diff -bur --no-dereference --new-file /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/query.sql /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/query.sql
--- /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/query.sql	1970-01-01 00:00:00.000000000 +0000
+++ /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/query.sql	2024-12-16 20:33:00.000000000 +0000
@@ -0,0 +1,92 @@
+WITH searches_per_user_by_country_and_date_staging AS (
+  SELECT
+    submission_date_s3,
+    country,
+    SUM(search_count_all) AS searches,
+    COUNT(DISTINCT client_id) AS users,
+  FROM
+    `moz-fx-data-shared-prod.telemetry.clients_daily`
+  WHERE
+    submission_date_s3 = @submission_date
+    AND app_name = 'Firefox'
+    AND sample_id = 42
+    AND search_count_all < 10000
+  GROUP BY
+    submission_date_s3,
+    country
+),
+searches_per_user_by_country_and_date AS (
+  SELECT
+    submission_date_s3,
+    country,
+    searches / users AS searches_per_user_ratio,
+  FROM
+    searches_per_user_by_country_and_date_staging
+),
+subsession_hours_per_user_staging AS (
+  SELECT
+    submission_date_s3,
+    country,
+    SUM(subsession_hours_sum) AS `hours`,
+    COUNT(DISTINCT client_id) AS users,
+  FROM
+    `moz-fx-data-shared-prod.telemetry.clients_daily`
+  WHERE
+    submission_date_s3 = @submission_date
+    AND app_name = 'Firefox'
+    AND sample_id = 42
+    AND subsession_hours_sum < 24
+  GROUP BY
+    submission_date_s3,
+    country
+),
+subsession_hours_per_user AS (
+  SELECT
+    submission_date_s3,
+    country,
+    `hours` / users AS subsession_hours_per_user_ratio
+  FROM
+    subsession_hours_per_user_staging
+),
+active_hours_per_user_staging AS (
+  SELECT
+    submission_date_s3,
+    country,
+    SUM(active_hours_sum) AS `hours`,
+    COUNT(DISTINCT(client_id)) AS users,
+  FROM
+    `moz-fx-data-shared-prod.telemetry.clients_daily`
+  WHERE
+    submission_date_s3 = @submission_date
+    AND app_name = 'Firefox'
+    AND sample_id = 42
+    AND active_hours_sum < 24
+  GROUP BY
+    submission_date_s3,
+    country
+),
+active_hours_per_user AS (
+  SELECT
+    submission_date_s3,
+    country,
+    `hours` / users AS active_hours_per_user_ratio
+  FROM
+    active_hours_per_user_staging
+)
+SELECT
+  COALESCE(
+    COALESCE(spu.submission_date_s3, sshpu.submission_date_s3),
+    ahpu.submission_date_s3
+  ) AS submission_date,
+  COALESCE(COALESCE(spu.country, sshpu.country), ahpu.country) AS country,
+  spu.searches_per_user_ratio,
+  sshpu.subsession_hours_per_user_ratio,
+  ahpu.active_hours_per_user_ratio
+FROM
+  searches_per_user_by_country_and_date AS spu
+FULL OUTER JOIN
+  subsession_hours_per_user AS sshpu
+  ON spu.country = sshpu.country
+FULL OUTER JOIN
+  active_hours_per_user AS ahpu
+  ON COALESCE(spu.country, sshpu.country) = ahpu.country
diff -bur --no-dereference --new-file /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/schema.yaml /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/schema.yaml
--- /tmp/workspace/main-generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/schema.yaml	1970-01-01 00:00:00.000000000 +0000
+++ /tmp/workspace/generated-sql/sql/moz-fx-data-shared-prod/telemetry_derived/fx_health_ind_clients_daily_by_country_v1/schema.yaml	2024-12-16 20:33:00.000000000 +0000
@@ -0,0 +1,21 @@
+fields:
+- mode: NULLABLE
+  name: submission_date
+  type: DATE
+  description: Submission Date
+- mode: NULLABLE
+  name: country
+  type: STRING
+  description: Country
+- mode: NULLABLE
+  name: searches_per_user_ratio
+  type: FLOAT
+  description: Ratio of Searches per User
+- mode: NULLABLE
+  name: subsession_hours_per_user_ratio
+  type: NUMERIC
+  description: Ratio of Subsession Hours per User
+- mode: NULLABLE
+  name: active_hours_per_user_ratio
+  type: FLOAT
+  description: Ratio of Active Hours per User

Link to full diff

@dataops-ci-bot
Copy link

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Integration report for "Create new aggregate table for Firefox Health Indicators dashboard (#6678)"

sql.diff

No content detected.

Please sign in to comment.