@@ -30,6 +30,31 @@ CREATE TEMP FUNCTION IS_NON_ZERO(
30
30
) RETURNS BOOL AS (
31
31
good + needs_improvement + poor > 0
32
32
);
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
+ """;
33
58
` ) . query ( ctx => `
34
59
WITH pages AS (
35
60
SELECT
@@ -172,7 +197,6 @@ technologies AS (
172
197
WHERE
173
198
tech.technology IS NOT NULL
174
199
175
-
176
200
UNION ALL
177
201
178
202
SELECT
@@ -183,26 +207,7 @@ technologies AS (
183
207
FROM pages
184
208
),
185
209
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 (
206
211
SELECT
207
212
client,
208
213
page,
@@ -213,36 +218,168 @@ lab_metrics AS (
213
218
SAFE.FLOAT64(lighthouse.categories.accessibility.score) AS accessibility,
214
219
SAFE.FLOAT64(lighthouse.categories['best-practices'].score) AS best_practices,
215
220
SAFE.FLOAT64(lighthouse.categories.performance.score) AS performance,
216
- SAFE.FLOAT64(lighthouse.categories.pwa.score) AS pwa,
217
221
SAFE.FLOAT64(lighthouse.categories.seo.score) AS seo
218
222
FROM pages
219
223
),
220
224
221
- lab_data AS (
225
+ audits AS (
226
+ SELECT DISTINCT
227
+ client,
228
+ root_page,
229
+ technology,
230
+ version,
231
+ audit_category,
232
+ audit_id
233
+ FROM (
234
+ SELECT
235
+ client,
236
+ page,
237
+ root_page,
238
+ audits.category AS audit_category,
239
+ audits.id AS audit_id
240
+ FROM pages
241
+ INNER JOIN UNNEST(get_passed_audits(pages.lighthouse)) AS audits
242
+ ) AS audits_data
243
+ INNER JOIN technologies
244
+ USING (client, page)
245
+ ),
246
+
247
+ lab_metrics AS (
222
248
SELECT
223
249
client,
224
250
root_page,
225
251
technology,
226
252
version,
227
- ANY_VALUE(category) AS category,
228
253
AVG(bytesTotal) AS bytesTotal,
229
254
AVG(bytesJS) AS bytesJS,
230
255
AVG(bytesImg) AS bytesImg,
231
256
AVG(accessibility) AS accessibility,
232
257
AVG(best_practices) AS best_practices,
233
258
AVG(performance) AS performance,
234
- AVG(pwa) AS pwa,
235
259
AVG(seo) AS seo
236
- FROM lab_metrics
260
+ FROM lab_data
237
261
INNER JOIN technologies
238
262
USING (client, page)
239
- INNER JOIN categories
240
- USING (technology)
241
263
GROUP BY
242
264
client,
243
265
root_page,
244
266
technology,
245
267
version
268
+ ),
269
+
270
+ origins_summary AS (
271
+ SELECT
272
+ geo,
273
+ client,
274
+ rank,
275
+ technology,
276
+ version,
277
+ COUNT(DISTINCT root_page) AS origins
278
+ FROM lab_metrics
279
+ INNER JOIN crux
280
+ USING (client, root_page)
281
+ GROUP BY
282
+ geo,
283
+ client,
284
+ rank,
285
+ technology,
286
+ version
287
+
288
+ ),
289
+
290
+
291
+ audits_summary AS (
292
+ SELECT
293
+ geo,
294
+ client,
295
+ rank,
296
+ technology,
297
+ version,
298
+ ARRAY_AGG(STRUCT(
299
+ audit_category AS category,
300
+ audit_id AS id,
301
+ SAFE_DIVIDE(audits.origins, origins_summary.origins) AS pass_rate
302
+ )) AS audits
303
+ FROM (
304
+ SELECT
305
+ geo,
306
+ client,
307
+ rank,
308
+ technology,
309
+ version,
310
+ audit_category,
311
+ audit_id,
312
+ COUNT(DISTINCT root_page) AS origins
313
+ FROM audits
314
+ INNER JOIN crux
315
+ USING (client, root_page)
316
+ GROUP BY
317
+ geo,
318
+ client,
319
+ rank,
320
+ technology,
321
+ version,
322
+ audit_category,
323
+ audit_id
324
+ ) AS audits
325
+ LEFT JOIN origins_summary
326
+ USING (geo, client, rank, technology, version)
327
+ GROUP BY
328
+ geo,
329
+ client,
330
+ rank,
331
+ technology,
332
+ version
333
+ ),
334
+
335
+ other_summary AS (
336
+ SELECT
337
+ geo,
338
+ client,
339
+ rank,
340
+ technology,
341
+ version,
342
+
343
+ STRUCT(
344
+ COUNTIF(good_fid) AS origins_with_good_fid,
345
+ COUNTIF(good_cls) AS origins_with_good_cls,
346
+ COUNTIF(good_lcp) AS origins_with_good_lcp,
347
+ COUNTIF(good_fcp) AS origins_with_good_fcp,
348
+ COUNTIF(good_ttfb) AS origins_with_good_ttfb,
349
+ COUNTIF(good_inp) AS origins_with_good_inp,
350
+ COUNTIF(any_fid) AS origins_with_any_fid,
351
+ COUNTIF(any_cls) AS origins_with_any_cls,
352
+ COUNTIF(any_lcp) AS origins_with_any_lcp,
353
+ COUNTIF(any_fcp) AS origins_with_any_fcp,
354
+ COUNTIF(any_ttfb) AS origins_with_any_ttfb,
355
+ COUNTIF(any_inp) AS origins_with_any_inp,
356
+ COUNTIF(good_cwv) AS origins_with_good_cwv,
357
+ COUNTIF(any_lcp AND any_cls) AS origins_eligible_for_cwv,
358
+ SAFE_DIVIDE(COUNTIF(good_cwv), COUNTIF(any_lcp AND any_cls)) AS pct_eligible_origins_with_good_cwv
359
+ ) AS crux,
360
+
361
+ STRUCT(
362
+ SAFE_CAST(APPROX_QUANTILES(accessibility, 1000)[OFFSET(500)] AS NUMERIC) AS accessibility,
363
+ SAFE_CAST(APPROX_QUANTILES(best_practices, 1000)[OFFSET(500)] AS NUMERIC) AS practices,
364
+ SAFE_CAST(APPROX_QUANTILES(performance, 1000)[OFFSET(500)] AS NUMERIC) AS performance,
365
+ SAFE_CAST(APPROX_QUANTILES(seo, 1000)[OFFSET(500)] AS NUMERIC) AS seo
366
+ ) AS median_lighthouse_score,
367
+
368
+ STRUCT(
369
+ SAFE_CAST(APPROX_QUANTILES(bytesTotal, 1000)[OFFSET(500)] AS INT64) AS total,
370
+ SAFE_CAST(APPROX_QUANTILES(bytesJS, 1000)[OFFSET(500)] AS INT64) AS js,
371
+ SAFE_CAST(APPROX_QUANTILES(bytesImg, 1000)[OFFSET(500)] AS INT64) AS images
372
+ ) AS median_page_weight_bytes
373
+
374
+ FROM lab_metrics
375
+ INNER JOIN crux
376
+ USING (client, root_page)
377
+ GROUP BY
378
+ geo,
379
+ client,
380
+ rank,
381
+ technology,
382
+ version
246
383
)
247
384
248
385
SELECT
@@ -252,44 +389,16 @@ SELECT
252
389
rank,
253
390
technology,
254
391
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
392
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
285
-
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
393
+ # Metrics
394
+ origins,
395
+ crux,
396
+ median_lighthouse_score,
397
+ median_page_weight_bytes,
398
+ audits
399
+ FROM origins_summary
400
+ LEFT JOIN other_summary
401
+ USING (geo, client, rank, technology, version)
402
+ LEFT JOIN audits_summary
403
+ USING (geo, client, rank, technology, version)
295
404
` )
0 commit comments