diff --git a/definitions/output/core_web_vitals/technologies.js b/definitions/output/core_web_vitals/technologies.js index d307929..84362b2 100644 --- a/definitions/output/core_web_vitals/technologies.js +++ b/definitions/output/core_web_vitals/technologies.js @@ -30,20 +30,105 @@ CREATE TEMP FUNCTION IS_NON_ZERO( ) RETURNS BOOL AS ( good + needs_improvement + poor > 0 ); + +CREATE TEMP FUNCTION extract_audits (lighthouse JSON) +RETURNS ARRAY> +LANGUAGE js AS """ +const results = [] +const performance_audits = lighthouse?.categories ? lighthouse.categories.performance.auditRefs + .filter((audit) => audit.group === "diagnostics") + .map((audit) => audit.id) : null + +if(performance_audits) { + for (const [key, audit] of Object.entries(lighthouse.audits)) { + if ( + performance_audits.includes(audit.id) && + audit.score !== null && + audit.scoreDisplayMode === 'metricSavings' + ) { + results.push({ + id: audit.id, + savings_ms: audit?.details?.overallSavingsMs || audit?.numericUnit === 'millisecond' ? audit.numericValue : null, + savings_bytes: audit?.details?.overallSavingsBytes || audit?.numericUnit === 'byte' ? audit.numericValue : null, + }) + } + } + return results; +} else { + return null; +} +"""; `).query(ctx => ` -WITH geo_summary AS ( +WITH pages AS ( + SELECT + client, + page, + root_page AS origin, + technologies, + summary, + lighthouse + FROM ${ctx.ref('crawl', 'pages')} + WHERE + date = '${pastMonth}' + ${constants.devRankFilter} +), geo_summary AS ( SELECT - CAST(REGEXP_REPLACE(CAST(yyyymm AS STRING), r'(\\d{4})(\\d{2})', r'\\1-\\2-01') AS DATE) AS date, - * EXCEPT (country_code), - \`chrome-ux-report\`.experimental.GET_COUNTRY(country_code) AS geo + \`chrome-ux-report\`.experimental.GET_COUNTRY(country_code) AS geo, + rank, + device, + origin, + avg_fcp, + avg_fid, + avg_inp, + avg_lcp, + avg_ttfb, + fast_fcp, + fast_fid, + fast_inp, + fast_lcp, + fast_ttfb, + slow_fcp, + slow_fid, + slow_inp, + slow_lcp, + slow_ttfb, + small_cls, + medium_cls, + large_cls FROM ${ctx.ref('chrome-ux-report', 'materialized', 'country_summary')} WHERE yyyymm = CAST(FORMAT_DATE('%Y%m', '${pastMonth}') AS INT64) AND device IN ('desktop', 'phone') -UNION ALL + + UNION ALL + SELECT - * EXCEPT (yyyymmdd, p75_fid_origin, p75_cls_origin, p75_lcp_origin, p75_inp_origin), - 'ALL' AS geo + 'ALL' AS geo, + rank, + device, + origin, + avg_fcp, + avg_fid, + avg_inp, + avg_lcp, + avg_ttfb, + fast_fcp, + fast_fid, + fast_inp, + fast_lcp, + fast_ttfb, + slow_fcp, + slow_fid, + slow_inp, + slow_lcp, + slow_ttfb, + small_cls, + medium_cls, + large_cls FROM ${ctx.ref('chrome-ux-report', 'materialized', 'device_summary')} WHERE date = '${pastMonth}' AND @@ -61,7 +146,7 @@ crux AS ( WHEN 10000 THEN 'Top 10k' WHEN 1000 THEN 'Top 1k' END AS rank, - CONCAT(origin, '/') AS root_page, + CONCAT(origin, '/') AS origin, IF(device = 'desktop', 'desktop', 'mobile') AS client, # CWV @@ -92,58 +177,63 @@ crux AS ( WHERE rank <= _rank ), +/* +audits AS ( + SELECT + client, + page, + performance_opportunities.id + FROM pages, + UNNEST(extract_audits(lighthouse)) AS performance_opportunities + WHERE + performance_opportunities.savings_ms > 0 OR + performance_opportunities.savings_bytes > 0 +), +*/ + technologies AS ( SELECT - technology.technology, + tech.technology, client, page - FROM ${ctx.ref('crawl', 'pages')}, - UNNEST(technologies) AS technology - WHERE - date = '${pastMonth}' - ${constants.devRankFilter} AND - technology.technology IS NOT NULL AND - technology.technology != '' -UNION ALL + FROM pages, + UNNEST(technologies) AS tech + + UNION ALL + SELECT 'ALL' AS technology, client, page - FROM ${ctx.ref('crawl', 'pages')} - WHERE - date = '${pastMonth}' - ${constants.devRankFilter} + FROM pages ), categories AS ( SELECT technology.technology, ARRAY_TO_STRING(ARRAY_AGG(DISTINCT category IGNORE NULLS ORDER BY category), ', ') AS category - FROM ${ctx.ref('crawl', 'pages')}, + FROM pages, UNNEST(technologies) AS technology, UNNEST(technology.categories) AS category - WHERE - date = '${pastMonth}' - ${constants.devRankFilter} GROUP BY technology -UNION ALL + + UNION ALL + SELECT 'ALL' AS technology, ARRAY_TO_STRING(ARRAY_AGG(DISTINCT category IGNORE NULLS ORDER BY category), ', ') AS category - FROM ${ctx.ref('crawl', 'pages')}, + FROM pages, UNNEST(technologies) AS technology, UNNEST(technology.categories) AS category WHERE - date = '${pastMonth}' AND client = 'mobile' - ${constants.devRankFilter} ), -summary_stats AS ( +lab_metrics AS ( SELECT client, page, - root_page AS root_page, + origin, SAFE.INT64(summary.bytesTotal) AS bytesTotal, SAFE.INT64(summary.bytesJS) AS bytesJS, SAFE.INT64(summary.bytesImg) AS bytesImg, @@ -151,17 +241,15 @@ summary_stats AS ( SAFE.FLOAT64(lighthouse.categories['best-practices'].score) AS best_practices, SAFE.FLOAT64(lighthouse.categories.performance.score) AS performance, SAFE.FLOAT64(lighthouse.categories.pwa.score) AS pwa, - SAFE.FLOAT64(lighthouse.categories.seo.score) AS seo - FROM ${ctx.ref('crawl', 'pages')} - WHERE - date = '${pastMonth}' - ${constants.devRankFilter} + SAFE.FLOAT64(lighthouse.categories.seo.score) AS seo, + extract_audits(lighthouse) AS performance_opportunities, + FROM pages ), lab_data AS ( SELECT client, - root_page, + origin, technology, ANY_VALUE(category) AS category, AVG(bytesTotal) AS bytesTotal, @@ -172,14 +260,14 @@ lab_data AS ( AVG(performance) AS performance, AVG(pwa) AS pwa, AVG(seo) AS seo - FROM summary_stats - JOIN technologies + FROM lab_metrics + INNER JOIN technologies USING (client, page) - JOIN categories + INNER JOIN categories USING (technology) GROUP BY client, - root_page, + origin, technology ) @@ -190,7 +278,7 @@ SELECT ANY_VALUE(category) AS category, technology AS app, client, - COUNT(0) AS origins, + COUNT(DISTINCT origin) AS origins, # CrUX data COUNTIF(good_fid) AS origins_with_good_fid, @@ -220,6 +308,11 @@ SELECT SAFE_CAST(APPROX_QUANTILES(pwa, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_pwa, SAFE_CAST(APPROX_QUANTILES(seo, 1000)[OFFSET(500)] AS NUMERIC) AS median_lighthouse_score_seo, + SAFE_DIVIDE(COUNTIF(accessibility >= 0.9), COUNTIF(accessibility > 0)) AS lighthouse_score_accessibility_pass_rate, + SAFE_DIVIDE(COUNTIF(best_practices >= 0.9), COUNTIF(best_practices > 0)) AS lighthouse_score_best_practices_pass_rate, + SAFE_DIVIDE(COUNTIF(performance >= 0.9), COUNTIF(performance > 0)) AS lighthouse_score_performance_pass_rate, + SAFE_DIVIDE(COUNTIF(seo >= 0.9), COUNTIF(seo > 0)) AS lighthouse_score_seo_pass_rate, + # Page weight stats SAFE_CAST(APPROX_QUANTILES(bytesTotal, 1000)[OFFSET(500)] AS INT64) AS median_bytes_total, SAFE_CAST(APPROX_QUANTILES(bytesJS, 1000)[OFFSET(500)] AS INT64) AS median_bytes_js, @@ -227,7 +320,7 @@ SELECT FROM lab_data INNER JOIN crux -USING (client, root_page) +USING (client, origin) GROUP BY app, geo,