Skip to content

Commit

Permalink
Merge branch 'main' into http2024-markdown
Browse files Browse the repository at this point in the history
  • Loading branch information
tunetheweb committed Nov 10, 2024
2 parents 74050b4 + ef6e5de commit 30deb8e
Show file tree
Hide file tree
Showing 58 changed files with 1,231 additions and 13 deletions.
51 changes: 51 additions & 0 deletions sql/2024/cms/cms_adoption_by_rank_all.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,51 @@
#standardSQL
# CMS adoption per rank
SELECT
client,
rank_grouping,
CASE rank_grouping
WHEN 1e8 THEN 'all'
ELSE TRIM(CAST(rank_grouping AS STRING FORMAT '99,999,999'))
END AS rank_grouping_text,
COUNT(DISTINCT page) AS pages,
MAX(total) AS total,
COUNT(DISTINCT page) / MAX(total) AS pct
FROM (
SELECT
client,
page,
rank_grouping
FROM
`httparchive.all.pages`,
UNNEST(technologies) AS tech,
UNNEST(tech.categories) AS category,
UNNEST([1e3, 1e4, 1e5, 1e6, 1e7, 1e8]) AS rank_grouping
WHERE
date = '2024-06-01' AND
rank <= rank_grouping AND
is_root_page AND
category = 'CMS'
)
JOIN (
SELECT
client,
rank_grouping,
COUNT(0) AS total
FROM
`httparchive.all.pages`,
UNNEST([1e3, 1e4, 1e5, 1e6, 1e7, 1e8]) AS rank_grouping
WHERE
date = '2024-06-01' AND
rank <= rank_grouping AND
is_root_page
GROUP BY
client,
rank_grouping)
USING
(client, rank_grouping)
GROUP BY
client,
rank_grouping
ORDER BY
rank_grouping,
pages DESC
25 changes: 25 additions & 0 deletions sql/2024/page-weight/bytes_per_type.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
SELECT
percentile,
client,
is_root_page,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS total_kbytes,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesHtml') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS html_kbytes,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesJS') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS js_kbytes,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesCss') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS css_kbytes,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesImg') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS img_kbytes,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesOther') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS other_kbytes,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesHtmlDoc') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS html_doc_kbytes,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesFont') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS font_kbytes
FROM
`httparchive.all.pages`,
UNNEST([10, 25, 50, 75, 90, 100]) AS percentile
WHERE
date = '2024-06-01'
GROUP BY
percentile,
client,
is_root_page
ORDER BY
client,
is_root_page,
percentile
22 changes: 22 additions & 0 deletions sql/2024/page-weight/compression-usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
SELECT
client,
is_root_page,
COUNTIF(JSON_VALUE(lighthouse, '$.audits.uses-text-compression.score') IS NULL) AS null_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.uses-text-compression.score') AS FLOAT64) >= 0.9) AS pass_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.uses-text-compression.score') AS FLOAT64) < 0.9) AS fail_count,
COUNT(0) AS total,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.uses-text-compression.score') AS FLOAT64) >= 0.9) / COUNT(0) AS pct_pass,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.uses-text-compression.score') AS FLOAT64) < 0.9) / COUNT(0) AS pct_fail
FROM
`httparchive.all.pages`
WHERE
date = '2024-06-01'
GROUP BY
client,
is_root_page
ORDER BY
client,
is_root_page,
null_count,
pass_count,
fail_count
86 changes: 86 additions & 0 deletions sql/2024/page-weight/cwv_trend.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,86 @@
WITH metrics_data AS (
SELECT
date,
client,
CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64) AS bytes_total,
CAST(JSON_VALUE(lighthouse, '$.audits.largest-contentful-paint.numericValue') AS FLOAT64) AS lcp,
CAST(JSON_VALUE(lighthouse, '$.audits.cumulative-layout-shift.numericValue') AS FLOAT64) AS cls,
CAST(JSON_VALUE(lighthouse, '$.audits.total-blocking-time.numericValue') AS FLOAT64) AS tbt,
CAST(JSON_VALUE(lighthouse, '$.audits.first-contentful-paint.numericValue') AS FLOAT64) AS fcp,
CAST(JSON_VALUE(lighthouse, '$.audits.interactive.numericValue') AS FLOAT64) AS tti,
CAST(JSON_VALUE(lighthouse, '$.categories.performance.score') AS FLOAT64) AS performance_score
FROM
`httparchive.all.pages`
WHERE
date >= '2023-06-01' AND
date <= '2024-06-01' AND
EXTRACT(DAY FROM date) = 1 -- Only include data from the first day of each month
)
SELECT
date,
client,
COUNT(DISTINCT IF(bytes_total > 0, bytes_total, NULL)) AS total_pages,

-- Page Size metrics
ROUND(APPROX_QUANTILES(bytes_total, 1000)[OFFSET(100)] / 1024, 2) AS p10_page_size_kb,
ROUND(APPROX_QUANTILES(bytes_total, 1000)[OFFSET(250)] / 1024, 2) AS p25_page_size_kb,
ROUND(APPROX_QUANTILES(bytes_total, 1000)[OFFSET(500)] / 1024, 2) AS p50_page_size_kb,
ROUND(APPROX_QUANTILES(bytes_total, 1000)[OFFSET(750)] / 1024, 2) AS p75_page_size_kb,
ROUND(APPROX_QUANTILES(bytes_total, 1000)[OFFSET(900)] / 1024, 2) AS p90_page_size_kb,

-- LCP metrics
ROUND(APPROX_QUANTILES(lcp, 1000)[OFFSET(100)], 2) AS p10_lcp,
ROUND(APPROX_QUANTILES(lcp, 1000)[OFFSET(250)], 2) AS p25_lcp,
ROUND(APPROX_QUANTILES(lcp, 1000)[OFFSET(500)], 2) AS p50_lcp,
ROUND(APPROX_QUANTILES(lcp, 1000)[OFFSET(750)], 2) AS p75_lcp,
ROUND(APPROX_QUANTILES(lcp, 1000)[OFFSET(900)], 2) AS p90_lcp,

-- CLS metrics
ROUND(APPROX_QUANTILES(cls, 1000)[OFFSET(100)], 3) AS p10_cls,
ROUND(APPROX_QUANTILES(cls, 1000)[OFFSET(250)], 3) AS p25_cls,
ROUND(APPROX_QUANTILES(cls, 1000)[OFFSET(500)], 3) AS p50_cls,
ROUND(APPROX_QUANTILES(cls, 1000)[OFFSET(750)], 3) AS p75_cls,
ROUND(APPROX_QUANTILES(cls, 1000)[OFFSET(900)], 3) AS p90_cls,

-- TBT metrics (as a proxy for FID)
ROUND(APPROX_QUANTILES(tbt, 1000)[OFFSET(100)], 2) AS p10_tbt,
ROUND(APPROX_QUANTILES(tbt, 1000)[OFFSET(250)], 2) AS p25_tbt,
ROUND(APPROX_QUANTILES(tbt, 1000)[OFFSET(500)], 2) AS p50_tbt,
ROUND(APPROX_QUANTILES(tbt, 1000)[OFFSET(750)], 2) AS p75_tbt,
ROUND(APPROX_QUANTILES(tbt, 1000)[OFFSET(900)], 2) AS p90_tbt,

-- FCP metrics
ROUND(APPROX_QUANTILES(fcp, 1000)[OFFSET(100)], 2) AS p10_fcp,
ROUND(APPROX_QUANTILES(fcp, 1000)[OFFSET(250)], 2) AS p25_fcp,
ROUND(APPROX_QUANTILES(fcp, 1000)[OFFSET(500)], 2) AS p50_fcp,
ROUND(APPROX_QUANTILES(fcp, 1000)[OFFSET(750)], 2) AS p75_fcp,
ROUND(APPROX_QUANTILES(fcp, 1000)[OFFSET(900)], 2) AS p90_fcp,

-- TTI metrics
ROUND(APPROX_QUANTILES(tti, 1000)[OFFSET(100)], 2) AS p10_tti,
ROUND(APPROX_QUANTILES(tti, 1000)[OFFSET(250)], 2) AS p25_tti,
ROUND(APPROX_QUANTILES(tti, 1000)[OFFSET(500)], 2) AS p50_tti,
ROUND(APPROX_QUANTILES(tti, 1000)[OFFSET(750)], 2) AS p75_tti,
ROUND(APPROX_QUANTILES(tti, 1000)[OFFSET(900)], 2) AS p90_tti,

-- Performance Score metrics
ROUND(APPROX_QUANTILES(performance_score, 1000)[OFFSET(900)] * 100, 2) AS p10_performance_score,
ROUND(APPROX_QUANTILES(performance_score, 1000)[OFFSET(750)] * 100, 2) AS p25_performance_score,
ROUND(APPROX_QUANTILES(performance_score, 1000)[OFFSET(500)] * 100, 2) AS p50_performance_score,
ROUND(APPROX_QUANTILES(performance_score, 1000)[OFFSET(250)] * 100, 2) AS p75_performance_score,
ROUND(APPROX_QUANTILES(performance_score, 1000)[OFFSET(100)] * 100, 2) AS p90_performance_score,

-- Good CWV percentages
ROUND(COUNTIF(lcp <= 2500) / COUNT(0) * 100, 2) AS good_lcp_percent,
ROUND(COUNTIF(cls <= 0.1) / COUNT(0) * 100, 2) AS good_cls_percent,
ROUND(COUNTIF(tbt <= 300) / COUNT(0) * 100, 2) AS good_tbt_percent,
ROUND(COUNTIF(fcp <= 1800) / COUNT(0) * 100, 2) AS good_fcp_percent

FROM
metrics_data
GROUP BY
date,
client
ORDER BY
date DESC,
client
22 changes: 22 additions & 0 deletions sql/2024/page-weight/facades-usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
SELECT
client,
is_root_page,
COUNTIF(JSON_VALUE(lighthouse, '$.audits.third-party-facades.score') IS NULL) AS null_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.third-party-facades.score') AS FLOAT64) >= 0.9) AS pass_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.third-party-facades.score') AS FLOAT64) < 0.9) AS fail_count,
COUNT(0) AS total,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.third-party-facades.score') AS FLOAT64) >= 0.9) / COUNT(0) AS pct_pass,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.third-party-facades.score') AS FLOAT64) < 0.9) / COUNT(0) AS pct_fail
FROM
`httparchive.all.pages`
WHERE
date = '2024-06-01'
GROUP BY
client,
is_root_page
ORDER BY
client,
is_root_page,
null_count,
pass_count,
fail_count
22 changes: 22 additions & 0 deletions sql/2024/page-weight/minified_css_usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
SELECT
client,
is_root_page,
COUNTIF(JSON_VALUE(lighthouse, '$.audits.unminified-css.score') IS NULL) AS null_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-css.score') AS FLOAT64) >= 0.9) AS pass_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-css.score') AS FLOAT64) < 0.9) AS fail_count,
COUNT(0) AS total,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-css.score') AS FLOAT64) >= 0.9) / COUNT(0) AS pct_pass,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-css.score') AS FLOAT64) < 0.9) / COUNT(0) AS pct_fail
FROM
`httparchive.all.pages`
WHERE
date = '2024-06-01'
GROUP BY
client,
is_root_page
ORDER BY
client,
is_root_page,
null_count,
pass_count,
fail_count
22 changes: 22 additions & 0 deletions sql/2024/page-weight/minified_js_usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
SELECT
client,
is_root_page,
COUNTIF(JSON_VALUE(lighthouse, '$.audits.unminified-javascript.score') IS NULL) AS null_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-javascript.score') AS FLOAT64) >= 0.9) AS pass_count,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-javascript.score') AS FLOAT64) < 0.9) AS fail_count,
COUNT(0) AS total,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-javascript.score') AS FLOAT64) >= 0.9) / COUNT(0) AS pct_pass,
COUNTIF(SAFE_CAST(JSON_VALUE(lighthouse, '$.audits.unminified-javascript.score') AS FLOAT64) < 0.9) / COUNT(0) AS pct_fail
FROM
`httparchive.all.pages`
WHERE
date = '2024-06-01'
GROUP BY
client,
is_root_page
ORDER BY
client,
is_root_page,
null_count,
pass_count,
fail_count
23 changes: 23 additions & 0 deletions sql/2024/page-weight/page_weight_trend.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
SELECT
date,
client,
is_root_page,
ROUND(APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64), 1000)[OFFSET(100)] / 1024, 2) AS p10,
ROUND(APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64), 1000)[OFFSET(250)] / 1024, 2) AS p25,
ROUND(APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64), 1000)[OFFSET(500)] / 1024, 2) AS p50,
ROUND(APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64), 1000)[OFFSET(750)] / 1024, 2) AS p75,
ROUND(APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64), 1000)[OFFSET(900)] / 1024, 2) AS p90
FROM
`httparchive.all.pages`
WHERE
date >= '2023-06-01' AND date <= '2024-06-01' AND -- Adjust this range as needed
CAST(JSON_VALUE(summary, '$.bytesTotal') AS INT64) > 0 AND
EXTRACT(DAY FROM date) = 1 -- Only include data from the first day of each month
GROUP BY
date,
client,
is_root_page
ORDER BY
date DESC,
client,
is_root_page
25 changes: 25 additions & 0 deletions sql/2024/page-weight/request_type_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
SELECT
percentile,
client,
is_root_page,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqTotal') AS INT64), 1000)[OFFSET(percentile * 10)] AS total_req,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqHtml') AS INT64), 1000)[OFFSET(percentile * 10)] AS html_req,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqJS') AS INT64), 1000)[OFFSET(percentile * 10)] AS js_req,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqCss') AS INT64), 1000)[OFFSET(percentile * 10)] AS css_req,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqImg') AS INT64), 1000)[OFFSET(percentile * 10)] AS img_req,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqJson') AS INT64), 1000)[OFFSET(percentile * 10)] AS json_req,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqOther') AS INT64), 1000)[OFFSET(percentile * 10)] AS other_req,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.reqFont') AS INT64), 1000)[OFFSET(percentile * 10)] AS font_req
FROM
`httparchive.all.pages`,
UNNEST([10, 25, 50, 75, 90, 100]) AS percentile
WHERE
date = '2024-06-01' -- Adjust this date as needed
GROUP BY
percentile,
client,
is_root_page
ORDER BY
client,
is_root_page,
percentile
21 changes: 21 additions & 0 deletions sql/2024/page-weight/response_format_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
SELECT
client,
percentile,
CAST(JSON_VALUE(summary, '$.type') AS STRING) AS format,
is_root_page,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.respBodySize') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS resp_size
FROM
`httparchive.all.requests`,
UNNEST([10, 25, 50, 75, 90, 100]) AS percentile
WHERE
date = '2024-06-01' -- Adjust this date as needed
GROUP BY
client,
percentile,
format,
is_root_page
ORDER BY
format,
client,
is_root_page,
percentile
21 changes: 21 additions & 0 deletions sql/2024/page-weight/response_type_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
SELECT
client,
percentile,
CAST(JSON_VALUE(summary, '$.type') AS STRING) AS type,
is_root_page,
APPROX_QUANTILES(CAST(JSON_VALUE(summary, '$.respSize') AS INT64) / 1024, 1000)[OFFSET(percentile * 10)] AS resp_size
FROM
`httparchive.all.requests`,
UNNEST([10, 25, 50, 75, 90, 100]) AS percentile
WHERE
date = '2024-06-01' -- Adjust this date as needed
GROUP BY
client,
percentile,
type,
is_root_page
ORDER BY
client,
type,
is_root_page,
percentile
3 changes: 1 addition & 2 deletions src/config/2024.json
Original file line number Diff line number Diff line change
Expand Up @@ -119,8 +119,7 @@
"part": "III",
"chapter_number": "14",
"title": "CMS",
"slug": "cms",
"todo": true
"slug": "cms"
},
{
"part": "III",
Expand Down
Loading

0 comments on commit 30deb8e

Please sign in to comment.