diff --git a/sql/2021/performance/lcp_element.sql b/sql/2021/performance/lcp_element.sql new file mode 100644 index 00000000000..72f51980ba3 --- /dev/null +++ b/sql/2021/performance/lcp_element.sql @@ -0,0 +1,29 @@ +#standardSQL +# LCP element node +# This is a simplified query - the lcp_element_data.sql one will probably be used instead. Leaving this here for reference for now. + +SELECT + _TABLE_SUFFIX AS client, + JSON_EXTRACT_SCALAR(payload, "$._performance.lcp_elem_stats[0].nodeName") AS lcp_node, + COUNT(DISTINCT url) AS pages, + ANY_VALUE(total) AS total, + COUNT(DISTINCT url) / ANY_VALUE(total) AS pct +FROM + `httparchive.pages.2021_07_01_*` +JOIN ( + SELECT + _TABLE_SUFFIX, + COUNT(0) AS total + FROM + `httparchive.summary_pages.2021_07_01_*` + GROUP BY + _TABLE_SUFFIX) +USING + (_TABLE_SUFFIX) +GROUP BY + client, + lcp_node +HAVING + pages > 1000 +ORDER BY + pct DESC diff --git a/sql/2021/performance/lcp_element_data.sql b/sql/2021/performance/lcp_element_data.sql new file mode 100644 index 00000000000..2c1128b0b47 --- /dev/null +++ b/sql/2021/performance/lcp_element_data.sql @@ -0,0 +1,80 @@ +#standardSQL +# LCP element node details + +CREATE TEMP FUNCTION getLoadingAttr(attributes STRING) RETURNS STRING LANGUAGE js AS ''' + try { + const data = JSON.parse(attributes); + const loadingAttr = data.find(attr => attr["name"] === "loading") + return loadingAttr.value + } catch (e) { + return ""; + } +'''; + +CREATE TEMP FUNCTION getDecodingAttr(attributes STRING) RETURNS STRING LANGUAGE js AS ''' + try { + const data = JSON.parse(attributes); + const decodingAttr = data.find(attr => attr["name"] === "decoding") + return decodingAttr.value + } catch (e) { + return ""; + } +'''; + +CREATE TEMP FUNCTION getLoadingClasses(attributes STRING) RETURNS STRING LANGUAGE js AS ''' + try { + const data = JSON.parse(attributes); + const classes = data.find(attr => attr["name"] === "class").value + if (classes.indexOf('lazyload') !== -1) { + return classes + } else { + return "" + } + } catch (e) { + return ""; + } +'''; + +WITH +lcp_stats AS ( + SELECT + _TABLE_SUFFIX AS client, + url, + JSON_EXTRACT_SCALAR(payload, "$._performance.lcp_elem_stats[0].nodeName") AS nodeName, + JSON_EXTRACT_SCALAR(payload, "$._performance.lcp_elem_stats[0].url") AS elementUrl, + CAST(JSON_EXTRACT_SCALAR(payload, "$._performance.lcp_elem_stats[0].size") AS INT64) AS size, + CAST(JSON_EXTRACT_SCALAR(payload, "$._performance.lcp_elem_stats[0].loadTime") AS FLOAT64) AS loadTime, + CAST(JSON_EXTRACT_SCALAR(payload, "$._performance.lcp_elem_stats[0].startTime") AS FLOAT64) AS startTime, + CAST(JSON_EXTRACT_SCALAR(payload, "$._performance.lcp_elem_stats[0].renderTime") AS FLOAT64) AS renderTime, + JSON_EXTRACT(payload, "$._performance.lcp_elem_stats[0].attributes") AS attributes, + getLoadingAttr(JSON_EXTRACT(payload, "$._performance.lcp_elem_stats[0].attributes")) AS loading, + getDecodingAttr(JSON_EXTRACT(payload, "$._performance.lcp_elem_stats[0].attributes")) AS decoding, + getLoadingClasses(JSON_EXTRACT(payload, "$._performance.lcp_elem_stats[0].attributes")) AS classWithLazyload + FROM + `httparchive.pages.2021_07_01_*` +) + +SELECT + client, + nodeName, + COUNT(DISTINCT url) AS pages, + SUM(COUNT(DISTINCT url)) OVER (PARTITION BY client) AS total, + COUNT(DISTINCT url) / SUM(COUNT(DISTINCT url)) OVER (PARTITION BY client) AS pct, + COUNTIF(elementUrl != "") AS haveImages, + COUNTIF(elementUrl != "") / COUNT(DISTINCT url) AS pct_haveImages, + COUNTIF(loading = "eager") AS native_eagerload, + COUNTIF(loading = "lazy") AS native_lazyload, + COUNTIF(classWithLazyload != "") AS lazyload_class, + COUNTIF(classWithLazyload != "" OR loading = "lazy") AS probably_lazyLoaded, + COUNTIF(classWithLazyload != "" OR loading = "lazy") / COUNT(DISTINCT url) AS pct_prob_lazyloaded, + COUNTIF(decoding = "async") AS async_decoding, + COUNTIF(decoding = "sync") AS sync_decoding, + COUNTIF(decoding = "auto") AS auto_decoding +FROM + lcp_stats +GROUP BY + client, + nodeName +ORDER BY + client, + pct DESC diff --git a/sql/2021/performance/unused_css_histogram.sql b/sql/2021/performance/unused_css_histogram.sql new file mode 100644 index 00000000000..47beca578c2 --- /dev/null +++ b/sql/2021/performance/unused_css_histogram.sql @@ -0,0 +1,20 @@ +#standardSQL +# Histogram of unused CSS bytes per page + +SELECT + IF(unused_css_kbytes <= 500, CEIL(unused_css_kbytes / 10) * 10, 500) AS unused_css_kbytes, + COUNT(0) / SUM(COUNT(0)) OVER (PARTITION BY 0) AS pct, + COUNT(0) AS pages, + SUM(COUNT(0)) OVER (PARTITION BY 0) AS total, + --only interested in last max one as a 'surprising metric' + MAX(unused_css_kbytes) AS max_unused_css_kb +FROM ( + SELECT + url AS page, + CAST(JSON_EXTRACT(report, "$.audits.unused-css-rules.details.overallSavingsBytes") AS INT64) / 1024 AS unused_css_kbytes + FROM + `httparchive.lighthouse.2021_07_01_mobile`) +GROUP BY + unused_css_kbytes +ORDER BY + unused_css_kbytes diff --git a/sql/2021/performance/unused_css_js.sql b/sql/2021/performance/unused_css_js.sql new file mode 100644 index 00000000000..ed552132c3b --- /dev/null +++ b/sql/2021/performance/unused_css_js.sql @@ -0,0 +1,14 @@ +# standardSQL +# Distribution of unused CSS and JS + +SELECT + percentile, + APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(report, "$.audits.unused-javascript.details.overallSavingsBytes") AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS js_kilobytes, + APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(report, "$.audits.unused-css-rules.details.overallSavingsBytes") AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS css_kilobytes +FROM + `httparchive.lighthouse.2021_07_01_mobile`, + UNNEST([10, 25, 50, 75, 90, 100]) AS percentile +GROUP BY + percentile +ORDER BY + percentile diff --git a/sql/2021/performance/unused_js_histogram.sql b/sql/2021/performance/unused_js_histogram.sql new file mode 100644 index 00000000000..41194306a06 --- /dev/null +++ b/sql/2021/performance/unused_js_histogram.sql @@ -0,0 +1,20 @@ +#standardSQL +# Histogram of unused JS bytes per page + +SELECT + IF(unused_js_kbytes <= 1000, CEIL(unused_js_kbytes / 20) * 20, 1000) AS unused_js_kbytes, + COUNT(0) / SUM(COUNT(0)) OVER (PARTITION BY 0) AS pct, + COUNT(0) AS pages, + SUM(COUNT(0)) OVER (PARTITION BY 0) AS total, + --only interested in last max one as a 'surprising metric' + MAX(unused_js_kbytes) AS max_unused_js_kb +FROM ( + SELECT + url AS page, + CAST(JSON_EXTRACT(report, "$.audits.unused-javascript.details.overallSavingsBytes") AS INT64) / 1024 AS unused_js_kbytes + FROM + `httparchive.lighthouse.2021_07_01_mobile`) +GROUP BY + unused_js_kbytes +ORDER BY + unused_js_kbytes diff --git a/sql/2021/performance/web_vitals_by_country.sql b/sql/2021/performance/web_vitals_by_country.sql new file mode 100644 index 00000000000..8f5da36bddf --- /dev/null +++ b/sql/2021/performance/web_vitals_by_country.sql @@ -0,0 +1,154 @@ +#standardSQL +# Core WebVitals by country + +CREATE TEMP FUNCTION IS_GOOD (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + SAFE_DIVIDE(good, (good + needs_improvement + poor)) >= 0.75 +); + +CREATE TEMP FUNCTION IS_POOR (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + SAFE_DIVIDE(poor, (good + needs_improvement + poor)) >= 0.25 +); + +CREATE TEMP FUNCTION IS_NI (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + NOT IS_GOOD(good, needs_improvement, poor) AND + NOT IS_POOR(good, needs_improvement, poor) +); + +CREATE TEMP FUNCTION IS_NON_ZERO (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good + needs_improvement + poor > 0 +); + +WITH +base AS ( + SELECT + origin, + country_code, + + SUM(fast_fid) / SUM(fast_fid + avg_fid + slow_fid) AS fast_fid, + SUM(avg_fid) / SUM(fast_fid + avg_fid + slow_fid) AS avg_fid, + SUM(slow_fid) / SUM(fast_fid + avg_fid + slow_fid) AS slow_fid, + + SUM(fast_lcp) / SUM(fast_lcp + avg_lcp + slow_lcp) AS fast_lcp, + SUM(avg_lcp) / SUM(fast_lcp + avg_lcp + slow_lcp) AS avg_lcp, + SUM(slow_lcp) / SUM(fast_lcp + avg_lcp + slow_lcp) AS slow_lcp, + + SUM(small_cls) / SUM(small_cls + medium_cls + large_cls) AS small_cls, + SUM(medium_cls) / SUM(small_cls + medium_cls + large_cls) AS medium_cls, + SUM(large_cls) / SUM(small_cls + medium_cls + large_cls) AS large_cls, + + SUM(fast_fcp) / SUM(fast_fcp + avg_fcp + slow_fcp) AS fast_fcp, + SUM(avg_fcp) / SUM(fast_fcp + avg_fcp + slow_fcp) AS avg_fcp, + SUM(slow_fcp) / SUM(fast_fcp + avg_fcp + slow_fcp) AS slow_fcp, + + SUM(fast_ttfb) / SUM(fast_ttfb + avg_ttfb + slow_ttfb) AS fast_ttfb, + SUM(avg_ttfb) / SUM(fast_ttfb + avg_ttfb + slow_ttfb) AS avg_ttfb, + SUM(slow_ttfb) / SUM(fast_ttfb + avg_ttfb + slow_ttfb) AS slow_ttfb + + FROM + `chrome-ux-report.materialized.country_summary` + WHERE + yyyymm = 202107 + GROUP BY + origin, + country_code +) + +SELECT + `chrome-ux-report`.experimental.GET_COUNTRY(country_code) AS country, + + COUNT(DISTINCT origin) AS total_origins, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid) AND + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid) AND + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp) AND + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cwv_good, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_poor + +FROM + base +GROUP BY + country diff --git a/sql/2021/performance/web_vitals_by_device.sql b/sql/2021/performance/web_vitals_by_device.sql new file mode 100644 index 00000000000..c0647917da8 --- /dev/null +++ b/sql/2021/performance/web_vitals_by_device.sql @@ -0,0 +1,155 @@ +#standardSQL +# Core WebVitals by device + +CREATE TEMP FUNCTION IS_GOOD (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good / (good + needs_improvement + poor) >= 0.75 +); + +CREATE TEMP FUNCTION IS_NI (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good / (good + needs_improvement + poor) < 0.75 AND + poor / (good + needs_improvement + poor) < 0.25 +); + +CREATE TEMP FUNCTION IS_POOR (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + poor / (good + needs_improvement + poor) >= 0.25 +); + +CREATE TEMP FUNCTION IS_NON_ZERO (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good + needs_improvement + poor > 0 +); + +WITH +base AS ( + SELECT + date, + origin, + device, + + fast_fid, + avg_fid, + slow_fid, + + fast_lcp, + avg_lcp, + slow_lcp, + + small_cls, + medium_cls, + large_cls, + + fast_fcp, + avg_fcp, + slow_fcp, + + fast_ttfb, + avg_ttfb, + slow_ttfb + + FROM + `chrome-ux-report.materialized.device_summary` + WHERE + device IN ('desktop', 'phone') AND + date IN ('2020-08-01', '2021-07-01') +) + +SELECT + date, + device, + + COUNT(DISTINCT origin) AS total_origins, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + (NOT IS_NON_ZERO(fast_fid, avg_fid, slow_fid) OR IS_GOOD(fast_fid, avg_fid, slow_fid)) AND + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid) AND + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp) AND + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cwv_good, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_poor + +FROM + base +GROUP BY + date, + device diff --git a/sql/2021/performance/web_vitals_by_eff_connection_type.sql b/sql/2021/performance/web_vitals_by_eff_connection_type.sql new file mode 100644 index 00000000000..4016bc3dbd9 --- /dev/null +++ b/sql/2021/performance/web_vitals_by_eff_connection_type.sql @@ -0,0 +1,266 @@ +#standardSQL +# WebVitals by effective connection type + +CREATE TEMP FUNCTION IS_GOOD (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + SAFE_DIVIDE(good, (good + needs_improvement + poor)) >= 0.75 +); + +CREATE TEMP FUNCTION IS_NI (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + SAFE_DIVIDE(good, (good + needs_improvement + poor)) < 0.75 AND + SAFE_DIVIDE(poor, (good + needs_improvement + poor)) < 0.25 +); + +CREATE TEMP FUNCTION IS_POOR (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + SAFE_DIVIDE(poor, (good + needs_improvement + poor)) >= 0.25 +); + +CREATE TEMP FUNCTION IS_NON_ZERO (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good + needs_improvement + poor > 0 +); + +WITH +base AS ( + SELECT + origin, + effective_connection_type.name AS network, + layout_instability, + largest_contentful_paint, + first_input, + first_contentful_paint, + experimental.time_to_first_byte AS time_to_first_byte + FROM + `chrome-ux-report.all.202107` +), + +cls AS ( + SELECT + origin, + network, + SUM(IF(bin.start < 0.1, bin.density, 0)) AS small, + SUM(IF(bin.start > 0.1 AND bin.start < 0.25, bin.density, 0)) AS medium, + SUM(IF(bin.start >= 0.25, bin.density, 0)) AS large, + `chrome-ux-report`.experimental.PERCENTILE_NUMERIC(ARRAY_AGG(bin), 75) AS p75 + FROM + base + LEFT JOIN + UNNEST(layout_instability.cumulative_layout_shift.histogram.bin) AS bin + GROUP BY + origin, + network +), + +lcp AS ( + SELECT + origin, + network, + SUM(IF(bin.start < 2500, bin.density, 0)) AS fast, + SUM(IF(bin.start >= 2500 AND bin.start < 4000, bin.density, 0)) AS avg, + SUM(IF(bin.start >= 4000, bin.density, 0)) AS slow, + `chrome-ux-report`.experimental.PERCENTILE(ARRAY_AGG(bin), 75) AS p75 + FROM + base + LEFT JOIN + UNNEST(largest_contentful_paint.histogram.bin) AS bin + GROUP BY + origin, + network +), + +fid AS ( + SELECT + origin, + network, + SUM(IF(bin.start < 100, bin.density, 0)) AS fast, + SUM(IF(bin.start >= 100 AND bin.start < 300, bin.density, 0)) AS avg, + SUM(IF(bin.start >= 300, bin.density, 0)) AS slow, + `chrome-ux-report`.experimental.PERCENTILE(ARRAY_AGG(bin), 75) AS p75 + FROM + base + LEFT JOIN + UNNEST(first_input.delay.histogram.bin) AS bin + GROUP BY + origin, + network +), + +fcp AS ( + SELECT + origin, + network, + SUM(IF(bin.start < 1500, bin.density, 0)) AS fast, + SUM(IF(bin.start >= 1500 AND bin.start < 2500, bin.density, 0)) AS avg, + SUM(IF(bin.start >= 2500, bin.density, 0)) AS slow, + `chrome-ux-report`.experimental.PERCENTILE(ARRAY_AGG(bin), 75) AS p75 + FROM + base + LEFT JOIN + UNNEST(first_contentful_paint.histogram.bin) AS bin + GROUP BY + origin, + network +), + +ttfb AS ( + SELECT + origin, + network, + SUM(IF(bin.start < 500, bin.density, 0)) AS fast, + SUM(IF(bin.start >= 500 AND bin.start < 1500, bin.density, 0)) AS avg, + SUM(IF(bin.start >= 1500, bin.density, 0)) AS slow, + `chrome-ux-report`.experimental.PERCENTILE(ARRAY_AGG(bin), 75) AS p75 + FROM + base + LEFT JOIN + UNNEST(time_to_first_byte.histogram.bin) AS bin + GROUP BY + origin, + network +), + +granular_metrics AS ( + SELECT + origin, + network, + cls.small AS small_cls, + cls.medium AS medium_cls, + cls.large AS large_cls, + cls.p75 AS p75_cls, + + lcp.fast AS fast_lcp, + lcp.avg AS avg_lcp, + lcp.slow AS slow_lcp, + lcp.p75 AS p75_lcp, + + fid.fast AS fast_fid, + fid.avg AS avg_fid, + fid.slow AS slow_fid, + fid.p75 AS p75_fid, + + fcp.fast AS fast_fcp, + fcp.avg AS avg_fcp, + fcp.slow AS slow_fcp, + fcp.p75 AS p75_fcp, + + ttfb.fast AS fast_ttfb, + ttfb.avg AS avg_ttfb, + ttfb.slow AS slow_ttfb, + ttfb.p75 AS p75_ttfb + FROM + cls + LEFT JOIN + lcp + USING + (origin, network) + LEFT JOIN + fid + USING + (origin, network) + LEFT JOIN + fcp + USING + (origin, network) + LEFT JOIN + ttfb + USING + (origin, network) +) + +SELECT + network, + + COUNT(DISTINCT origin) AS total_origins, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid) AND + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid) AND + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp) AND + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cwv_good, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_poor + +FROM + granular_metrics +GROUP BY + network diff --git a/sql/2021/performance/web_vitals_by_rank.sql b/sql/2021/performance/web_vitals_by_rank.sql new file mode 100644 index 00000000000..597c0e39e70 --- /dev/null +++ b/sql/2021/performance/web_vitals_by_rank.sql @@ -0,0 +1,162 @@ +#standardSQL +# Core WebVitals by rank + +CREATE TEMP FUNCTION IS_GOOD (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good / (good + needs_improvement + poor) >= 0.75 +); + +CREATE TEMP FUNCTION IS_NI (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good / (good + needs_improvement + poor) < 0.75 AND + poor / (good + needs_improvement + poor) < 0.25 +); + +CREATE TEMP FUNCTION IS_POOR (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + poor / (good + needs_improvement + poor) >= 0.25 +); + +CREATE TEMP FUNCTION IS_NON_ZERO (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good + needs_improvement + poor > 0 +); + +WITH +base AS ( + SELECT + date, + origin, + rank, + + fast_fid, + avg_fid, + slow_fid, + + fast_lcp, + avg_lcp, + slow_lcp, + + small_cls, + medium_cls, + large_cls, + + fast_fcp, + avg_fcp, + slow_fcp, + + fast_ttfb, + avg_ttfb, + slow_ttfb + + FROM + `chrome-ux-report.materialized.metrics_summary` + WHERE + date IN ('2021-07-01') +) + +SELECT + date, + CASE + WHEN rank_grouping = 10000000 THEN 'all' + ELSE CAST(rank_grouping AS STRING) + END AS ranking, + + COUNT(DISTINCT origin) AS total_origins, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid) AND + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid) AND + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp) AND + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cwv_good, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_poor + +FROM + base, + UNNEST([1000, 10000, 100000, 1000000, 10000000]) AS rank_grouping +WHERE + rank <= rank_grouping +GROUP BY + date, + rank_grouping +ORDER BY + rank_grouping diff --git a/sql/2021/performance/web_vitals_by_rank_and_device.sql b/sql/2021/performance/web_vitals_by_rank_and_device.sql new file mode 100644 index 00000000000..8720c6c6ae0 --- /dev/null +++ b/sql/2021/performance/web_vitals_by_rank_and_device.sql @@ -0,0 +1,166 @@ +#standardSQL +# Core WebVitals by rank and device + +CREATE TEMP FUNCTION IS_GOOD (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good / (good + needs_improvement + poor) >= 0.75 +); + +CREATE TEMP FUNCTION IS_NI (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good / (good + needs_improvement + poor) < 0.75 AND + poor / (good + needs_improvement + poor) < 0.25 +); + +CREATE TEMP FUNCTION IS_POOR (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + poor / (good + needs_improvement + poor) >= 0.25 +); + +CREATE TEMP FUNCTION IS_NON_ZERO (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS ( + good + needs_improvement + poor > 0 +); + +WITH +base AS ( + SELECT + date, + origin, + device, + rank, + + fast_fid, + avg_fid, + slow_fid, + + fast_lcp, + avg_lcp, + slow_lcp, + + small_cls, + medium_cls, + large_cls, + + fast_fcp, + avg_fcp, + slow_fcp, + + fast_ttfb, + avg_ttfb, + slow_ttfb + + FROM + `chrome-ux-report.materialized.device_summary` + WHERE + device IN ('desktop', 'phone') AND + date IN ('2021-07-01') +) + +SELECT + date, + device, + CASE + WHEN rank_grouping = 10000000 THEN 'all' + ELSE CAST(rank_grouping AS STRING) + END AS ranking, + + COUNT(DISTINCT origin) AS total_origins, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + (IS_GOOD(fast_fid, avg_fid, slow_fid) OR fast_fid IS NULL) AND + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid) AND + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp) AND + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cwv_good, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_lcp, avg_lcp, slow_lcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp), origin, NULL))) AS pct_lcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fid, avg_fid, slow_fid), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fid, avg_fid, slow_fid), origin, NULL))) AS pct_fid_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(small_cls, medium_cls, large_cls), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_cls_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_fcp, avg_fcp, slow_fcp), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_fcp, avg_fcp, slow_fcp), origin, NULL))) AS pct_fcp_poor, + + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_good, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_NI(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_ni, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_POOR(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL)), + COUNT(DISTINCT IF( + IS_NON_ZERO(fast_ttfb, avg_ttfb, slow_ttfb), origin, NULL))) AS pct_ttfb_poor + +FROM + base, + UNNEST([1000, 10000, 100000, 1000000, 10000000]) AS rank_grouping +WHERE + rank <= rank_grouping +GROUP BY + date, + device, + rank_grouping +ORDER BY + rank_grouping