Skip to content

Commit 55529ec

Browse files
committed
audits pass rates
1 parent 8bde2fb commit 55529ec

File tree

3 files changed

+247
-67
lines changed

3 files changed

+247
-67
lines changed

definitions/output/reports/tech_crux.js

+154-65
Original file line numberDiff line numberDiff line change
@@ -30,6 +30,31 @@ CREATE TEMP FUNCTION IS_NON_ZERO(
3030
) RETURNS BOOL AS (
3131
good + needs_improvement + poor > 0
3232
);
33+
34+
CREATE TEMP FUNCTION get_passed_audits(lighthouse JSON)
35+
RETURNS ARRAY<STRUCT<
36+
category STRING,
37+
id STRING
38+
>>
39+
LANGUAGE js AS """
40+
const results = []
41+
42+
for (const category of Object.keys(lighthouse?.categories ? lighthouse.categories : {})) {
43+
for (const audit of lighthouse.categories[category].auditRefs) {
44+
if (
45+
lighthouse.audits[audit.id].score === 1 &&
46+
!['metrics', 'hidden'].includes(audit.group)
47+
) {
48+
results.push({
49+
category,
50+
id: audit.id
51+
})
52+
}
53+
}
54+
}
55+
56+
return results;
57+
""";
3358
`).query(ctx => `
3459
WITH pages AS (
3560
SELECT
@@ -172,7 +197,6 @@ technologies AS (
172197
WHERE
173198
tech.technology IS NOT NULL
174199
175-
176200
UNION ALL
177201
178202
SELECT
@@ -183,26 +207,7 @@ technologies AS (
183207
FROM pages
184208
),
185209
186-
categories AS (
187-
SELECT
188-
tech.technology,
189-
ARRAY_TO_STRING(ARRAY_AGG(DISTINCT category IGNORE NULLS ORDER BY category), ', ') AS category
190-
FROM pages,
191-
UNNEST(technologies) AS tech,
192-
UNNEST(tech.categories) AS category
193-
GROUP BY technology
194-
195-
UNION ALL
196-
197-
SELECT
198-
'ALL' AS technology,
199-
ARRAY_TO_STRING(ARRAY_AGG(DISTINCT category IGNORE NULLS ORDER BY category), ', ') AS category
200-
FROM pages,
201-
UNNEST(technologies) AS tech,
202-
UNNEST(tech.categories) AS category
203-
),
204-
205-
lab_metrics AS (
210+
lab_data AS (
206211
SELECT
207212
client,
208213
page,
@@ -218,13 +223,76 @@ lab_metrics AS (
218223
FROM pages
219224
),
220225
221-
lab_data AS (
226+
audits AS (
227+
SELECT DISTINCT
228+
client,
229+
root_page,
230+
technology,
231+
version,
232+
audit_category,
233+
audit_id
234+
FROM (
235+
SELECT
236+
client,
237+
page,
238+
root_page,
239+
audits.category AS audit_category,
240+
audits.id AS audit_id
241+
FROM pages
242+
INNER JOIN UNNEST(get_passed_audits(pages.lighthouse)) AS audits
243+
) AS audits_data
244+
INNER JOIN technologies
245+
USING (client, page)
246+
),
247+
248+
audits_summary AS (
249+
SELECT
250+
geo,
251+
client,
252+
rank,
253+
technology,
254+
version,
255+
ARRAY_AGG(STRUCT(
256+
audit_category AS category,
257+
audit_id AS id,
258+
origins
259+
)) AS audits
260+
FROM (
261+
SELECT
262+
geo,
263+
client,
264+
rank,
265+
technology,
266+
version,
267+
audit_category,
268+
audit_id,
269+
COUNT(DISTINCT root_page) AS origins
270+
FROM audits
271+
INNER JOIN crux
272+
USING (client, root_page)
273+
GROUP BY
274+
geo,
275+
client,
276+
rank,
277+
technology,
278+
version,
279+
audit_category,
280+
audit_id
281+
)
282+
GROUP BY
283+
geo,
284+
client,
285+
rank,
286+
technology,
287+
version
288+
),
289+
290+
lab_metrics AS (
222291
SELECT
223292
client,
224293
root_page,
225294
technology,
226295
version,
227-
ANY_VALUE(category) AS category,
228296
AVG(bytesTotal) AS bytesTotal,
229297
AVG(bytesJS) AS bytesJS,
230298
AVG(bytesImg) AS bytesImg,
@@ -233,16 +301,67 @@ lab_data AS (
233301
AVG(performance) AS performance,
234302
AVG(pwa) AS pwa,
235303
AVG(seo) AS seo
236-
FROM lab_metrics
304+
FROM lab_data
237305
INNER JOIN technologies
238306
USING (client, page)
239-
INNER JOIN categories
240-
USING (technology)
241307
GROUP BY
242308
client,
243309
root_page,
244310
technology,
245311
version
312+
),
313+
314+
first_summary AS (
315+
SELECT
316+
geo,
317+
client,
318+
rank,
319+
technology,
320+
version,
321+
322+
COUNT(DISTINCT root_page) AS origins,
323+
324+
STRUCT(
325+
COUNTIF(good_fid) AS origins_with_good_fid,
326+
COUNTIF(good_cls) AS origins_with_good_cls,
327+
COUNTIF(good_lcp) AS origins_with_good_lcp,
328+
COUNTIF(good_fcp) AS origins_with_good_fcp,
329+
COUNTIF(good_ttfb) AS origins_with_good_ttfb,
330+
COUNTIF(good_inp) AS origins_with_good_inp,
331+
COUNTIF(any_fid) AS origins_with_any_fid,
332+
COUNTIF(any_cls) AS origins_with_any_cls,
333+
COUNTIF(any_lcp) AS origins_with_any_lcp,
334+
COUNTIF(any_fcp) AS origins_with_any_fcp,
335+
COUNTIF(any_ttfb) AS origins_with_any_ttfb,
336+
COUNTIF(any_inp) AS origins_with_any_inp,
337+
COUNTIF(good_cwv) AS origins_with_good_cwv,
338+
COUNTIF(any_lcp AND any_cls) AS origins_eligible_for_cwv,
339+
SAFE_DIVIDE(COUNTIF(good_cwv), COUNTIF(any_lcp AND any_cls)) AS pct_eligible_origins_with_good_cwv
340+
) AS crux,
341+
342+
STRUCT(
343+
SAFE_CAST(APPROX_QUANTILES(accessibility, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_accessibility,
344+
SAFE_CAST(APPROX_QUANTILES(best_practices, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_best_practices,
345+
SAFE_CAST(APPROX_QUANTILES(performance, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_performance,
346+
SAFE_CAST(APPROX_QUANTILES(pwa, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_pwa,
347+
SAFE_CAST(APPROX_QUANTILES(seo, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_seo
348+
) AS lighthouse,
349+
350+
STRUCT(
351+
SAFE_CAST(APPROX_QUANTILES(bytesTotal, 1000)[OFFSET(500)] AS INT64) AS median_bytes_total,
352+
SAFE_CAST(APPROX_QUANTILES(bytesJS, 1000)[OFFSET(500)] AS INT64) AS median_bytes_js,
353+
SAFE_CAST(APPROX_QUANTILES(bytesImg, 1000)[OFFSET(500)] AS INT64) AS median_bytes_image
354+
) AS page_weight
355+
356+
FROM lab_metrics
357+
INNER JOIN crux
358+
USING (client, root_page)
359+
GROUP BY
360+
geo,
361+
client,
362+
rank,
363+
technology,
364+
version
246365
)
247366
248367
SELECT
@@ -252,44 +371,14 @@ SELECT
252371
rank,
253372
technology,
254373
version,
255-
COUNT(DISTINCT root_page) AS origins,
256-
257-
# CrUX data
258-
COUNTIF(good_fid) AS origins_with_good_fid,
259-
COUNTIF(good_cls) AS origins_with_good_cls,
260-
COUNTIF(good_lcp) AS origins_with_good_lcp,
261-
COUNTIF(good_fcp) AS origins_with_good_fcp,
262-
COUNTIF(good_ttfb) AS origins_with_good_ttfb,
263-
COUNTIF(good_inp) AS origins_with_good_inp,
264-
COUNTIF(any_fid) AS origins_with_any_fid,
265-
COUNTIF(any_cls) AS origins_with_any_cls,
266-
COUNTIF(any_lcp) AS origins_with_any_lcp,
267-
COUNTIF(any_fcp) AS origins_with_any_fcp,
268-
COUNTIF(any_ttfb) AS origins_with_any_ttfb,
269-
COUNTIF(any_inp) AS origins_with_any_inp,
270-
COUNTIF(good_cwv) AS origins_with_good_cwv,
271-
COUNTIF(any_lcp AND any_cls) AS origins_eligible_for_cwv,
272-
SAFE_DIVIDE(COUNTIF(good_cwv), COUNTIF(any_lcp AND any_cls)) AS pct_eligible_origins_with_good_cwv,
273-
274-
# Lighthouse data
275-
SAFE_CAST(APPROX_QUANTILES(accessibility, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_accessibility,
276-
SAFE_CAST(APPROX_QUANTILES(best_practices, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_best_practices,
277-
SAFE_CAST(APPROX_QUANTILES(performance, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_performance,
278-
SAFE_CAST(APPROX_QUANTILES(pwa, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_pwa,
279-
SAFE_CAST(APPROX_QUANTILES(seo, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_seo,
280-
281-
# Page weight stats
282-
SAFE_CAST(APPROX_QUANTILES(bytesTotal, 1000)[OFFSET(500)] AS INT64) AS median_bytes_total,
283-
SAFE_CAST(APPROX_QUANTILES(bytesJS, 1000)[OFFSET(500)] AS INT64) AS median_bytes_js,
284-
SAFE_CAST(APPROX_QUANTILES(bytesImg, 1000)[OFFSET(500)] AS INT64) AS median_bytes_image
285374
286-
FROM lab_data
287-
INNER JOIN crux
288-
USING (client, root_page)
289-
GROUP BY
290-
geo,
291-
client,
292-
rank,
293-
technology,
294-
version
375+
# Metrics
376+
origins,
377+
crux,
378+
lighthouse,
379+
page_weight,
380+
audits
381+
FROM first_summary
382+
INNER JOIN audits_summary
383+
USING (geo, client, rank, technology, version)
295384
`)
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,89 @@
1+
const pastMonth = constants.fnPastMonth(constants.currentMonth)
2+
3+
publish('tech_report_audits', {
4+
schema: 'reports',
5+
type: 'incremental',
6+
protected: true,
7+
bigquery: {
8+
partitionBy: 'date',
9+
clusterBy: ['rank', 'geo']
10+
},
11+
tags: ['tech_report']
12+
}).preOps(ctx => `
13+
CREATE TEMP FUNCTION GET_AUDITS(
14+
records ARRAY<STRUCT<
15+
client STRING,
16+
audits ARRAY<STRUCT<
17+
category STRING,
18+
id STRING,
19+
origins INT64
20+
>>
21+
>>
22+
)
23+
RETURNS ARRAY<STRUCT<
24+
category STRING,
25+
id STRING,
26+
mobile STRUCT<
27+
origins INT64
28+
>,
29+
desktop STRUCT<
30+
origins INT64
31+
>
32+
>>
33+
LANGUAGE js AS '''
34+
// Create a map to accumulate audits based on a unique key (category + id).
35+
var auditMap = {};
36+
37+
// Loop over each record.
38+
records.forEach(function(record) {
39+
// Loop over each audit in the record.
40+
record.audits.forEach(function(audit) {
41+
// Create a unique key for combining audits.
42+
var key = audit.category + '|' + audit.id;
43+
// Initialize the audit in the map if not present.
44+
if (!auditMap[key]) {
45+
auditMap[key] = {
46+
category: audit.category,
47+
id: audit.id,
48+
mobile: { origins: 0 },
49+
desktop: { origins: 0 }
50+
};
51+
}
52+
// Add the origins to the proper client type.
53+
if (record.client === 'mobile') {
54+
auditMap[key].mobile.origins += audit.origins;
55+
} else if (record.client === 'desktop') {
56+
auditMap[key].desktop.origins += audit.origins;
57+
}
58+
});
59+
});
60+
61+
// Convert the map into an array of audits.
62+
return Object.keys(auditMap).map(function(key) {
63+
return auditMap[key];
64+
});
65+
''';
66+
67+
DELETE FROM ${ctx.self()}
68+
WHERE date = '${pastMonth}';
69+
`).query(ctx => `
70+
/* {"dataform_trigger": "tech_report_complete", "date": "${pastMonth}", "name": "audits", "type": "report"} */
71+
SELECT
72+
date,
73+
geo,
74+
rank,
75+
technology,
76+
version,
77+
GET_AUDITS(ARRAY_AGG(STRUCT(
78+
client,
79+
audits
80+
))) AS audits
81+
FROM ${ctx.ref('reports', 'tech_crux')}
82+
WHERE date = '${pastMonth}'
83+
GROUP BY
84+
date,
85+
geo,
86+
rank,
87+
technology,
88+
version
89+
`)

definitions/output/reports/tech_report_lighthouse.js

+4-2
Original file line numberDiff line numberDiff line change
@@ -18,15 +18,17 @@ CREATE TEMPORARY FUNCTION GET_LIGHTHOUSE(
1818
median_lighthouse_score_performance NUMERIC,
1919
median_lighthouse_score_pwa NUMERIC,
2020
median_lighthouse_score_seo NUMERIC
21-
>>)
21+
>>
22+
)
2223
RETURNS ARRAY<STRUCT<
2324
name STRING,
2425
desktop STRUCT<
2526
median_score FLOAT64
2627
>,
2728
mobile STRUCT<
2829
median_score FLOAT64
29-
>>>
30+
>
31+
>>
3032
LANGUAGE js AS '''
3133
const METRIC_MAP = {
3234
accessibility: 'median_lighthouse_score_accessibility',

0 commit comments

Comments
 (0)