Skip to content

Commit 4819ecc

Browse files
authored
add process to sample counts glam tables (#2751)
add process to sample counts glam tables add process to extract tables add process to extract tables add sample counts for scalars and histogram
1 parent 3b77cfa commit 4819ecc

File tree

2 files changed

+151
-64
lines changed

2 files changed

+151
-64
lines changed
Lines changed: 76 additions & 29 deletions
Original file line numberDiff line numberDiff line change
@@ -1,33 +1,80 @@
1+
WITH sample_counts_filtered AS (
2+
SELECT
3+
CASE
4+
WHEN
5+
cp.channel = "nightly"
6+
THEN
7+
1
8+
WHEN
9+
cp.channel = "beta"
10+
THEN
11+
2
12+
WHEN
13+
cp.channel = "release"
14+
THEN
15+
3
16+
END
17+
AS channel,
18+
cp.app_version,
19+
cp.ping_type,
20+
COALESCE(cp.app_build_id, "*") AS app_build_id,
21+
COALESCE(cp.os, "*") AS os,
22+
cp.process,
23+
cp.metric,
24+
SUBSTR(REPLACE(cp.key, r"\x00", ""), 0, 200) AS key,
25+
client_agg_type,
26+
total_sample,
27+
FROM
28+
`{{ dataset }}.{{ prefix }}__view_probe_counts_v1` cp
29+
INNER JOIN `{{ dataset }}.{{ prefix }}__view_sample_counts_v1` sc
30+
ON
31+
sc.os = COALESCE(cp.os, "*")
32+
AND sc.app_build_id = COALESCE(cp.app_build_id, "*")
33+
AND sc.app_version = cp.app_version
34+
AND sc.metric = cp.metric
35+
AND sc.key = cp.key
36+
AND sc.ping_type = cp.ping_type,
37+
AND sc.process = cp.process
38+
AND total_sample IS NOT NULL
39+
WHERE
40+
cp.app_version IS NOT NULL
41+
AND cp.total_users > {{ total_users }}
42+
AND client_agg_type NOT IN ('sum', 'min', 'avg', 'max')
43+
),
44+
sample_counts_ranked AS (
45+
SELECT
46+
channel,
47+
app_version,
48+
ping_type,
49+
app_build_id,
50+
os,
51+
key,
52+
metric,
53+
total_sample,
54+
ROW_NUMBER() OVER (
55+
PARTITION BY
56+
channel,
57+
app_version,
58+
app_build_id,
59+
os,
60+
key,
61+
metric
62+
ORDER BY
63+
total_sample DESC
64+
) AS rnk
65+
FROM
66+
sample_counts_filtered
67+
)
168
SELECT
2-
cp.channel,
3-
cp.app_version,
4-
cp.ping_type,
5-
COALESCE(cp.app_build_id, "*") AS app_build_id,
6-
COALESCE(cp.os, "*") AS os,
7-
cp.metric,
8-
cp.key,
9-
cp.client_agg_type,
69+
channel,
70+
app_version,
71+
ping_type,
72+
app_build_id,
73+
os,
74+
key,
75+
metric,
1076
total_sample
1177
FROM
12-
`{{ dataset }}.{{ prefix }}__view_probe_counts_v1` cp
13-
LEFT JOIN `{{ dataset }}.{{ prefix }}__view_sample_counts_v1` sc
14-
ON sc.os=COALESCE(cp.os, "*")
15-
AND sc.app_build_id=COALESCE(cp.app_build_id, "*")
16-
AND sc.app_version=cp.app_version
17-
AND sc.metric=cp.metric
18-
AND cp.key=sc.key
19-
AND total_sample IS NOT NULL
78+
sample_counts_ranked
2079
WHERE
21-
cp.app_version IS NOT NULL
22-
AND total_users > {{ total_users }}
23-
AND cp.client_agg_type not in ('sum','min','avg','max')
24-
GROUP BY
25-
cp.channel,
26-
cp.ping_type,
27-
cp.app_version,
28-
cp.app_build_id,
29-
cp.os,
30-
cp.metric,
31-
cp.key,
32-
client_agg_type,
33-
total_sample
80+
rnk = 1
Lines changed: 75 additions & 35 deletions
Original file line numberDiff line numberDiff line change
@@ -1,39 +1,79 @@
1+
WITH sample_counts_filtered AS (
2+
SELECT
3+
CASE
4+
WHEN
5+
cp.channel = "nightly"
6+
THEN
7+
1
8+
WHEN
9+
cp.channel = "beta"
10+
THEN
11+
2
12+
WHEN
13+
cp.channel = "release"
14+
THEN
15+
3
16+
END
17+
AS channel,
18+
cp.app_version,
19+
COALESCE(cp.app_build_id, "*") AS app_build_id,
20+
COALESCE(cp.os, "*") AS os,
21+
cp.process,
22+
cp.metric,
23+
SUBSTR(REPLACE(cp.key, r"\x00", ""), 0, 200) AS key,
24+
client_agg_type,
25+
total_sample,
26+
FROM
27+
`moz-fx-data-shared-prod.telemetry.client_probe_counts` cp
28+
INNER JOIN
29+
`moz-fx-data-shared-prod.telemetry_derived.glam_sample_counts_v1` sc
30+
ON
31+
sc.os = COALESCE(cp.os, "*")
32+
AND sc.app_build_id = COALESCE(cp.app_build_id, "*")
33+
AND sc.app_version = cp.app_version
34+
AND sc.metric = cp.metric
35+
AND sc.key = cp.key
36+
AND sc.process = cp.process
37+
AND total_sample IS NOT NULL
38+
WHERE
39+
cp.app_version IS NOT NULL
40+
AND cp.total_users > 375
41+
AND client_agg_type NOT IN ('sum', 'min', 'avg', 'max')
42+
),
43+
sample_counts_ranked AS (
44+
SELECT
45+
channel,
46+
app_version,
47+
app_build_id,
48+
os,
49+
process,
50+
key,
51+
metric,
52+
total_sample,
53+
ROW_NUMBER() OVER (
54+
PARTITION BY
55+
channel,
56+
app_version,
57+
app_build_id,
58+
os,
59+
key,
60+
metric
61+
ORDER BY
62+
total_sample DESC
63+
) AS rnk
64+
FROM
65+
sample_counts_filtered
66+
)
167
SELECT
2-
CASE
3-
WHEN
4-
cp.channel = "nightly"
5-
THEN
6-
1
7-
WHEN
8-
cp.channel = "beta"
9-
THEN
10-
2
11-
WHEN
12-
cp.channel = "release"
13-
THEN
14-
3
15-
END
16-
AS channel,
17-
cp.app_version,
18-
COALESCE(cp.app_build_id, "*") AS app_build_id,
19-
COALESCE(cp.os, "*") AS os,
68+
channel,
69+
app_version,
70+
app_build_id,
71+
os,
2072
process,
21-
cp.metric,
22-
SUBSTR(REPLACE(cp.key, r"\x00", ""), 0, 200) AS key,
23-
client_agg_type,
24-
total_sample,
73+
key,
74+
metric,
75+
total_sample
2576
FROM
26-
`moz-fx-data-shared-prod.telemetry.client_probe_counts` cp
27-
LEFT JOIN
28-
`moz-fx-data-shared-prod.telemetry_derived.glam_sample_counts_v1` sc
29-
ON
30-
sc.os = COALESCE(cp.os, "*")
31-
AND sc.app_build_id = COALESCE(cp.app_build_id, "*")
32-
AND sc.app_version = cp.app_version
33-
AND sc.metric = cp.metric
34-
AND sc.key = cp.key
35-
AND total_sample IS NOT NULL
77+
sample_counts_ranked
3678
WHERE
37-
cp.app_version IS NOT NULL
38-
AND cp.total_users > 375
39-
AND client_agg_type NOT IN ('sum', 'min', 'avg', 'max')
79+
rnk = 1

0 commit comments

Comments
 (0)