Skip to content

Commit

Permalink
Jamstack 2020 queries (#1228)
Browse files Browse the repository at this point in the history
* add cdn_ttfb query

* Update cdn_ttfb.sql

* Add CWV for SSG

* Add CWV distribution, thirdparty requests

* Rename third party bytes

* Improve CWV passing, add ssg adoption comparing to 2019

* Add more queries

* Update sql/2020/17_JAMstack/cdn_core_web_vitals_distribution.sql

Co-authored-by: Rick Viscomi <[email protected]>

* Update sql/2020/17_JAMstack/cdn_core_web_vitals_distribution.sql

Co-authored-by: Rick Viscomi <[email protected]>

* Unitize ssg adoption query yoy

* Use firstHtml for summary_requests, adjust readme

* Add CO2, image adoption, LH median results

* Fix namings

* add image adoption queries

* Align WV query

* alignment

* Update sql/2020/17_JAMstack/core_web_vitals_distribution.sql

Co-authored-by: Rick Viscomi <[email protected]>

* Update sql/2020/17_JAMstack/median_lighthouse_score.sql

Co-authored-by: Rick Viscomi <[email protected]>

* Update sql/2020/17_JAMstack/core_web_vitals_passing.sql

Co-authored-by: Rick Viscomi <[email protected]>

* Update sql/2020/17_JAMstack/third_party_bytes_and_requests_on_ssgs.sql

Co-authored-by: Rick Viscomi <[email protected]>

Co-authored-by: Rick Viscomi <[email protected]>
  • Loading branch information
denar90 and rviscomi authored Oct 12, 2020
1 parent 96f0d3e commit 2815281
Show file tree
Hide file tree
Showing 8 changed files with 388 additions and 0 deletions.
6 changes: 6 additions & 0 deletions sql/2020/17_JAMstack/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
# Jamstack 2020

Related materials:

- [Planning doc](https://docs.google.com/document/d/1bz5b2iXTvz3hlaLQQCB0fhwx7A-nqLLRCauQHAkVsJA/edit)
- [Results spreadsheet](https://docs.google.com/spreadsheets/d/1BCC5Q4tePpTl8TiaGmSxBc9Lh2to7xBfVPMULFOBwvk/edit#gid=2077755325)
34 changes: 34 additions & 0 deletions sql/2020/17_JAMstack/adoption_of_image_formats_in_ssgs.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
#standardSQL
# Adoption of image formats in SSGs
SELECT
client,
format,
COUNT(0) AS freq,
SUM(COUNT(0)) OVER (PARTITION BY client) AS total,
COUNT(0) / SUM(COUNT(0)) OVER (PARTITION BY client) AS pct
FROM (
SELECT
client,
format,
page
FROM
`httparchive.almanac.requests`
WHERE
date = '2020-08-01' AND
type = 'image')
JOIN (
SELECT
_TABLE_SUFFIX AS client,
url AS page
FROM
`httparchive.technologies.2020_08_01_*`
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js")
USING
(client, page)
GROUP BY
client,
format
ORDER BY
pct DESC
71 changes: 71 additions & 0 deletions sql/2020/17_JAMstack/core_web_vitals_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,71 @@
#standardSQL
# Core Web Vitals distribution by SSG
#
# Note that this is an unweighted average of all sites per SSG.
# Performance of sites with millions of visitors as weighted the same as small sites.
SELECT
app,
CDN,
client,
COUNT(DISTINCT origin) AS origins,
SUM(fast_lcp) / (SUM(fast_lcp) + SUM(avg_lcp) + SUM(slow_lcp)) AS good_lcp,
SUM(avg_lcp) / (SUM(fast_lcp) + SUM(avg_lcp) + SUM(slow_lcp)) AS ni_lcp,
SUM(slow_lcp) / (SUM(fast_lcp) + SUM(avg_lcp) + SUM(slow_lcp)) AS poor_lcp,

SUM(fast_fid) / (SUM(fast_fid) + SUM(avg_fid) + SUM(slow_fid)) AS good_fid,
SUM(avg_fid) / (SUM(fast_fid) + SUM(avg_fid) + SUM(slow_fid)) AS ni_fid,
SUM(slow_fid) / (SUM(fast_fid) + SUM(avg_fid) + SUM(slow_fid)) AS poor_fid,

SUM(small_cls) / (SUM(small_cls) + SUM(medium_cls) + SUM(large_cls)) AS good_cls,
SUM(medium_cls) / (SUM(small_cls) + SUM(medium_cls) + SUM(large_cls)) AS ni_cls,
SUM(large_cls) / (SUM(small_cls) + SUM(medium_cls) + SUM(large_cls)) AS poor_cls,
FROM (
SELECT
IF(device = 'desktop', 'desktop', 'mobile') AS client,
CONCAT(origin, '/') AS url,
*
FROM
`chrome-ux-report.materialized.device_summary`
WHERE
date = '2020-08-01')
JOIN (
SELECT
CASE
WHEN REGEXP_EXTRACT(LOWER(CONCAT(respOtherHeaders, resp_x_powered_by, resp_via, resp_server)), '(x-github-request)') = 'x-github-request' THEN 'GitHub'
WHEN REGEXP_EXTRACT(LOWER(CONCAT(respOtherHeaders, resp_x_powered_by, resp_via, resp_server)), '(netlify)') = 'netlify' THEN 'Netlify'
WHEN _cdn_provider = 'Microsoft Azure' THEN 'Azure'
WHEN _cdn_provider = 'Vercel' THEN 'Vercel'
WHEN _cdn_provider = 'Amazon CloudFront' THEN 'AWS'
WHEN _cdn_provider = 'Akamai' THEN 'Akamai'
WHEN _cdn_provider = 'Cloudflare' THEN 'Cloudflare'
ELSE NULL
END AS CDN,
client,
page AS url
FROM
`httparchive.almanac.requests`
WHERE
date = '2020-08-01' AND
firstHtml)
USING
(client, url)
JOIN (
SELECT
_TABLE_SUFFIX AS client,
app,
url
FROM
`httparchive.technologies.2020_08_01_*`
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js"
)
USING (client, url)
WHERE
CDN IS NOT NULL
GROUP BY
app,
CDN,
client
ORDER BY
origins DESC
91 changes: 91 additions & 0 deletions sql/2020/17_JAMstack/core_web_vitals_passing.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,91 @@
#standardSQL
# Core Web Vitals performance by CMS
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_NON_ZERO (good FLOAT64, needs_improvement FLOAT64, poor FLOAT64) RETURNS BOOL AS (
good + needs_improvement + poor > 0
);


SELECT
app,
CDN,
client,
COUNT(DISTINCT origin) AS origins,
# Origins with good LCP divided by origins with any LCP.
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_good_lcp,

# Origins with good FID divided by origins with any FID.
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_good_fid,

# Origins with good CLS divided by origins with any CLS.
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_good_cls,

# Origins with good LCP, FID, and CLS dividied by origins with any LCP, FID, and CLS.
SAFE_DIVIDE(
COUNT(DISTINCT IF(
IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND
IS_GOOD(fast_fid, avg_fid, slow_fid) AND
IS_GOOD(small_cls, medium_cls, large_cls), origin, NULL)),
COUNT(DISTINCT IF(
IS_NON_ZERO(fast_lcp, avg_lcp, slow_lcp) AND
IS_NON_ZERO(fast_fid, avg_fid, slow_fid) AND
IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_good_cwv
FROM (
SELECT
IF(device = 'desktop', 'desktop', 'mobile') AS client,
CONCAT(origin, '/') AS url,
*
FROM
`chrome-ux-report.materialized.device_summary`
WHERE
date = '2020-08-01')
JOIN (
SELECT
CASE
WHEN REGEXP_EXTRACT(LOWER(CONCAT(respOtherHeaders, resp_x_powered_by, resp_via, resp_server)), '(x-github-request)') = 'x-github-request' THEN 'GitHub'
WHEN REGEXP_EXTRACT(LOWER(CONCAT(respOtherHeaders, resp_x_powered_by, resp_via, resp_server)), '(netlify)') = 'netlify' THEN 'Netlify'
WHEN _cdn_provider = 'Microsoft Azure' THEN 'Azure'
WHEN _cdn_provider = 'Vercel' THEN 'Vercel'
WHEN _cdn_provider = 'Amazon CloudFront' THEN 'AWS'
WHEN _cdn_provider = 'Akamai' THEN 'Akamai'
WHEN _cdn_provider = 'Cloudflare' THEN 'Cloudflare'
ELSE NULL
END AS CDN,
client,
page AS url
FROM
`httparchive.almanac.requests`
WHERE
date = '2020-08-01' AND
firstHtml)
USING
(client, url)
JOIN (
SELECT
_TABLE_SUFFIX AS client,
app,
url
FROM
`httparchive.technologies.2020_08_01_*`
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js"
)
USING (client, url)
WHERE
CDN IS NOT NULL
GROUP BY
app,
CDN,
client
ORDER BY
origins DESC
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
#standardSQL
# Distribution of page weight, requests, and co2 grams per SSG web page
# https://gitlab.com/wholegrain/carbon-api-2-0/-/blob/b498ec3bb239536d3612c5f3d758f46e0d2431a6/includes/carbonapi.php
CREATE TEMP FUNCTION
GREEN(url STRING) AS (FALSE); -- TODO: Investigate fetching from Green Web Foundation
CREATE TEMP FUNCTION
adjustDataTransfer(val INT64) AS (val * 0.75 + 0.02 * val * 0.25);
CREATE TEMP FUNCTION
energyConsumption(bytes FLOAT64) AS (bytes * 1.805 / 1073741824);
CREATE TEMP FUNCTION
getCo2Grid(energy FLOAT64) AS (energy * 475);
CREATE TEMP FUNCTION
getCo2Renewable(energy FLOAT64) AS (energy * 0.1008 * 33.4 + energy * 0.8992 * 475);
CREATE TEMP FUNCTION
CO2(url STRING, bytes INT64) AS (
IF
(GREEN(url),
getCo2Renewable(energyConsumption(adjustDataTransfer(bytes))),
getCo2Grid(energyConsumption(adjustDataTransfer(bytes)))));

SELECT
percentile,
client,
APPROX_QUANTILES(requests, 1000)[OFFSET(percentile * 10)] AS requests,
ROUND(APPROX_QUANTILES(bytes, 1000)[OFFSET(percentile * 10)] / 1024 / 1024, 2) AS mbytes,
APPROX_QUANTILES(co2grams, 1000)[OFFSET(percentile * 10)] AS co2grams
FROM (
SELECT
_TABLE_SUFFIX AS client,
reqTotal AS requests,
bytesTotal AS bytes,
CO2(url, bytesTotal) AS co2grams
FROM
`httparchive.summary_pages.2020_08_01_*`
JOIN (
SELECT
_TABLE_SUFFIX,
url
FROM
`httparchive.technologies.2020_08_01_*`
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js"
)
USING
(_TABLE_SUFFIX, url)),
UNNEST([10, 25, 50, 75, 90]) AS percentile
GROUP BY
percentile,
client
ORDER BY
percentile,
client
23 changes: 23 additions & 0 deletions sql/2020/17_JAMstack/median_lighthouse_score.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
#standardSQL
# Lighthouse category scores per SSG
SELECT
_TABLE_SUFFIX AS client,
app AS ssg,
COUNT(DISTINCT url) AS freq,
APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(report, '$.categories.performance.score') AS NUMERIC), 1000)[OFFSET(500)] AS median_performance,
APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(report, '$.categories.accessibility.score') AS NUMERIC), 1000)[OFFSET(500)] AS median_accessibility,
APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(report, '$.categories.pwa.score') AS NUMERIC), 1000)[OFFSET(500)] AS median_pwa
FROM
`httparchive.lighthouse.2020_09_01_*`
JOIN
`httparchive.technologies.2020_09_01_*`
USING
(_TABLE_SUFFIX, url)
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js"
GROUP BY
ssg,
client
ORDER BY
freq DESC
58 changes: 58 additions & 0 deletions sql/2020/17_JAMstack/ssg_compared_to_2019.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
#standardSQL
# SSG adoptions and top SSGs YoY
SELECT
_TABLE_SUFFIX AS client,
2020 AS year,
app AS ssg,
COUNT(0) AS freq,
total,
COUNT(0) / total AS pct
FROM
`httparchive.technologies.2020_08_01_*`
JOIN (
SELECT
_TABLE_SUFFIX,
COUNT(0) AS total
FROM
`httparchive.summary_pages.2020_08_01_*`
GROUP BY
_TABLE_SUFFIX)
USING
(_TABLE_SUFFIX)
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js"
GROUP BY
client,
total,
ssg
UNION ALL
SELECT
_TABLE_SUFFIX AS client,
2019 AS year,
app AS ssg,
COUNT(0) AS freq,
total,
COUNT(0) / total AS pct
FROM
`httparchive.technologies.2019_07_01_*`
JOIN (
SELECT
_TABLE_SUFFIX,
COUNT(0) AS total
FROM
`httparchive.summary_pages.2019_07_01_*`
GROUP BY
_TABLE_SUFFIX)
USING
(_TABLE_SUFFIX)
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js"
GROUP BY
client,
total,
ssg
ORDER BY
year DESC,
pct DESC
52 changes: 52 additions & 0 deletions sql/2020/17_JAMstack/third_party_bytes_and_requests_on_ssgs.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
#standardSQL
# Third party bytes and requests on SSGs
SELECT
percentile,
client,
APPROX_QUANTILES(requests, 1000)[OFFSET(percentile * 10)] AS requests,
APPROX_QUANTILES(bytes, 1000)[OFFSET(percentile * 10)] / 1024 AS kbytes
FROM (
SELECT
client,
COUNT(0) AS requests,
SUM(respSize) AS bytes
FROM (
SELECT
client,
page,
url,
respSize
FROM
`httparchive.almanac.requests`
WHERE
date = '2020-08-01')
JOIN (
SELECT
_TABLE_SUFFIX AS client,
url AS page
FROM
`httparchive.technologies.2020_08_01_*`
WHERE
LOWER(category) = "static site generator" OR
app = "Next.js")
USING
(client, page)
WHERE
NET.HOST(url) IN (
SELECT
domain
FROM
`httparchive.almanac.third_parties`
WHERE
date = '2020-08-01' AND
category != 'hosting')
GROUP BY
client,
page),
UNNEST([10, 25, 50, 75, 90, 100]) AS percentile
GROUP BY
percentile,
client
ORDER BY
percentile,
client

0 comments on commit 2815281

Please sign in to comment.