@@ -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,
@@ -218,13 +223,76 @@ lab_metrics AS (
218
223
FROM pages
219
224
),
220
225
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 (
222
291
SELECT
223
292
client,
224
293
root_page,
225
294
technology,
226
295
version,
227
- ANY_VALUE(category) AS category,
228
296
AVG(bytesTotal) AS bytesTotal,
229
297
AVG(bytesJS) AS bytesJS,
230
298
AVG(bytesImg) AS bytesImg,
@@ -233,16 +301,67 @@ lab_data AS (
233
301
AVG(performance) AS performance,
234
302
AVG(pwa) AS pwa,
235
303
AVG(seo) AS seo
236
- FROM lab_metrics
304
+ FROM lab_data
237
305
INNER JOIN technologies
238
306
USING (client, page)
239
- INNER JOIN categories
240
- USING (technology)
241
307
GROUP BY
242
308
client,
243
309
root_page,
244
310
technology,
245
311
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
246
365
)
247
366
248
367
SELECT
@@ -252,44 +371,14 @@ SELECT
252
371
rank,
253
372
technology,
254
373
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
285
374
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)
295
384
` )
0 commit comments