From d6c9dc054995be42877ceb980e6d9097b116842e Mon Sep 17 00:00:00 2001 From: Rick Viscomi Date: Sun, 29 Nov 2020 20:48:09 -0500 Subject: [PATCH 1/2] Update lh6_vs_lh5_performance_score_02.sql --- .../lh6_vs_lh5_performance_score_02.sql | 47 +++++++++++-------- 1 file changed, 27 insertions(+), 20 deletions(-) diff --git a/sql/2020/09_Performance/lh6_vs_lh5_performance_score_02.sql b/sql/2020/09_Performance/lh6_vs_lh5_performance_score_02.sql index 0cd98215338..8f7933110c7 100644 --- a/sql/2020/09_Performance/lh6_vs_lh5_performance_score_02.sql +++ b/sql/2020/09_Performance/lh6_vs_lh5_performance_score_02.sql @@ -1,30 +1,37 @@ #standardSQL - -# Calculates percentage of sites where the performance score changed low ( < 10), medium (10-30) or big (> 30) between -# LH 5 and 6 versions. - +# Calculates percentage of sites where the performance score changed small ( < 10), medium (10-30) or large (> 30) between LH 5 and 6 versions. SELECT - SAFE_DIVIDE(small_change, small_change + mid_change + big_change) AS small, - SAFE_DIVIDE(mid_change, small_change + mid_change + big_change) AS avg, - SAFE_DIVIDE(big_change, small_change + mid_change + big_change) AS big + direction, + magnitude, + pages AS freq, + SUM(pages) OVER () AS total, + pages / SUM(pages) OVER () AS pct FROM ( SELECT - COUNTIF(perf_score_delta <= 0.1) AS small_change, - COUNTIF(perf_score_delta > 0.1 AND perf_score_delta <= 0.3) AS mid_change, - COUNTIF(perf_score_delta > 0.3) AS big_change - FROM - ( + CASE + WHEN perf_score_delta < 0 THEN 'negative' + ELSE 'positive' + END AS direction, + CASE + WHEN ABS(perf_score_delta) <= 0.1 THEN 'small' + WHEN ABS(perf_score_delta) < 0.3 THEN 'large' + ELSE 'medium' + END AS magnitude, + COUNT(0) AS pages + FROM ( SELECT perf_score_lh6, perf_score_lh5, - (perf_score_lh6 - perf_score_lh5) AS perf_score_delta - FROM - ( + perf_score_lh6 - perf_score_lh5 AS perf_score_delta + FROM ( SELECT CAST(JSON_EXTRACT(lh6.report, '$.categories.performance.score') AS NUMERIC) AS perf_score_lh6, CAST(JSON_EXTRACT(lh5.report, '$.categories.performance.score') AS NUMERIC) AS perf_score_lh5 - FROM `httparchive.lighthouse.2020_09_01_mobile` lh6 - JOIN `httparchive.lighthouse.2019_07_01_mobile` lh5 ON lh5.url=lh6.url - ) - ) -) + FROM + `httparchive.lighthouse.2020_09_01_mobile` AS lh6 + JOIN + `httparchive.lighthouse.2019_07_01_mobile` AS lh5 + USING (url))) + GROUP BY + direction, + magnitude) From e46db0decea46ef9522efe1cfec93074b8df94d0 Mon Sep 17 00:00:00 2001 From: Rick Viscomi Date: Sun, 29 Nov 2020 21:20:37 -0500 Subject: [PATCH 2/2] Create lh6_vs_lh5_performance_score_distribution.sql --- ..._vs_lh5_performance_score_distribution.sql | 24 +++++++++++++++++++ 1 file changed, 24 insertions(+) create mode 100644 sql/2020/09_Performance/lh6_vs_lh5_performance_score_distribution.sql diff --git a/sql/2020/09_Performance/lh6_vs_lh5_performance_score_distribution.sql b/sql/2020/09_Performance/lh6_vs_lh5_performance_score_distribution.sql new file mode 100644 index 00000000000..cca54515984 --- /dev/null +++ b/sql/2020/09_Performance/lh6_vs_lh5_performance_score_distribution.sql @@ -0,0 +1,24 @@ +#standardSQL +SELECT + perf_score_delta, + COUNT(0) AS pages +FROM ( + SELECT + perf_score_lh6 - perf_score_lh5 AS perf_score_delta, + ROW_NUMBER() OVER (ORDER BY (perf_score_lh6 - perf_score_lh5)) AS row_number, + COUNT(0) OVER () AS n + FROM ( + SELECT + CAST(JSON_EXTRACT(lh6.report, '$.categories.performance.score') AS NUMERIC) AS perf_score_lh6, + CAST(JSON_EXTRACT(lh5.report, '$.categories.performance.score') AS NUMERIC) AS perf_score_lh5 + FROM + `httparchive.lighthouse.2020_09_01_mobile` AS lh6 + JOIN + `httparchive.lighthouse.2019_07_01_mobile` AS lh5 + USING (url))) +WHERE + perf_score_delta IS NOT NULL +GROUP BY + perf_score_delta +ORDER BY + perf_score_delta