From 216bf23edcda8cfe88409774d80a231bd1d69c0a Mon Sep 17 00:00:00 2001 From: Jonathan Pagel <63317370+jcmpagel@users.noreply.github.com> Date: Sat, 9 Nov 2024 21:31:19 +0100 Subject: [PATCH] Ecommerce 2024 queries (#3786) * Create top_vendors.sql * Create top_vendors_crux_rank.sql slightly adjusted ranks from 2021 * Create median_lighthouse_score_ecommsites.sql * Create core_web_vitals_passingmetrics_byvendor_bydevice.sql * Create top_analytics_providers_bydevice_wapp.sql * Create top_abtesting_bydevice.sql * Create percent_of_ecommsites_using_cmp.sql * Create top_cmp_bydevice.sql this is new. * Update top_vendors_crux_rank.sql updated for new schema * Delete sql/2024/ecommerce/top_vendors.sql included in the rank one * Update median_lighthouse_score_ecommsites.sql updated for new schema and also added rank for further analysis * Update median_lighthouse_score_ecommsites.sql * Update top_vendors_crux_rank.sql * Update median_lighthouse_score_ecommsites.sql * Update top_cmp_bydevice.sql * Update top_cmp_bydevice.sql * Delete sql/2024/ecommerce/percent_of_ecommsites_using_cmp.sql * Update core_web_vitals_passingmetrics_byvendor_bydevice.sql * Delete sql/2024/ecommerce/top_analytics_providers_bydevice_wapp.sql * Delete sql/2024/ecommerce/top_abtesting_bydevice.sql * Create top_shopsystem_by_geo.sql * Create core_web_vitals_yoy.sql * Create top_payment_by_geo.sql * Create top_shipping_by_geo.sql * Create top_shipping_yoy.sql * Create top_payment_yoy.sql * Delete sql/2024/ecommerce/top_cmp_bydevice.sql * Update top_vendors_crux_rank.sql Make it more like the CMS one to be 100% sure * Create top_ecommerce.sql * Update core_web_vitals_yoy.sql * Update core_web_vitals_yoy.sql remove havings * Update top_payment_yoy.sql * Update top_shipping_yoy.sql * Update top_ecommerce.sql * fix lintin errors --- ...itals_passingmetrics_byvendor_bydevice.sql | 66 ++++++ sql/2024/ecommerce/core_web_vitals_yoy.sql | 193 ++++++++++++++++++ .../median_lighthouse_score_ecommsites.sql | 43 ++++ sql/2024/ecommerce/top_ecommerce.sql | 141 +++++++++++++ sql/2024/ecommerce/top_payment_by_geo.sql | 68 ++++++ sql/2024/ecommerce/top_payment_yoy.sql | 137 +++++++++++++ sql/2024/ecommerce/top_shipping_by_geo.sql | 68 ++++++ sql/2024/ecommerce/top_shipping_yoy.sql | 137 +++++++++++++ sql/2024/ecommerce/top_shopsystem_by_geo.sql | 70 +++++++ sql/2024/ecommerce/top_vendors_crux_rank.sql | 63 ++++++ 10 files changed, 986 insertions(+) create mode 100644 sql/2024/ecommerce/core_web_vitals_passingmetrics_byvendor_bydevice.sql create mode 100644 sql/2024/ecommerce/core_web_vitals_yoy.sql create mode 100644 sql/2024/ecommerce/median_lighthouse_score_ecommsites.sql create mode 100644 sql/2024/ecommerce/top_ecommerce.sql create mode 100644 sql/2024/ecommerce/top_payment_by_geo.sql create mode 100644 sql/2024/ecommerce/top_payment_yoy.sql create mode 100644 sql/2024/ecommerce/top_shipping_by_geo.sql create mode 100644 sql/2024/ecommerce/top_shipping_yoy.sql create mode 100644 sql/2024/ecommerce/top_shopsystem_by_geo.sql create mode 100644 sql/2024/ecommerce/top_vendors_crux_rank.sql diff --git a/sql/2024/ecommerce/core_web_vitals_passingmetrics_byvendor_bydevice.sql b/sql/2024/ecommerce/core_web_vitals_passingmetrics_byvendor_bydevice.sql new file mode 100644 index 00000000000..d2e6e57f7f9 --- /dev/null +++ b/sql/2024/ecommerce/core_web_vitals_passingmetrics_byvendor_bydevice.sql @@ -0,0 +1,66 @@ +#standardSQL +# CrUX Core Web Vitals performance of Ecommerce vendors by device (fid was upated to inp, and is non optinal now) +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 + client, + ecomm, + 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 INP divided by origins with any inp. + SAFE_DIVIDE( + COUNT(DISTINCT IF(IS_GOOD(fast_inp, avg_inp, slow_inp), origin, NULL)), + COUNT(DISTINCT IF(IS_NON_ZERO(fast_inp, avg_inp, slow_inp), origin, NULL))) AS pct_good_inp, + + # 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, inp, and CLS divided by origins with any LCP, inp, and CLS. + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(fast_inp, avg_inp, slow_inp) 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_inp, avg_inp, slow_inp) AND + IS_NON_ZERO(small_cls, medium_cls, large_cls), origin, NULL))) AS pct_good_cwv +FROM + `chrome-ux-report.materialized.device_summary` +JOIN ( + SELECT + _TABLE_SUFFIX AS client, + url, + app AS ecomm + FROM + `httparchive.technologies.2024_06_01_*` + WHERE + category = 'Ecommerce' AND + ( + app != 'Cart Functionality' AND + app != 'Google Analytics Enhanced eCommerce' + ) + ) +ON + CONCAT(origin, '/') = url AND + IF(device = 'desktop', 'desktop', 'mobile') = client +WHERE + date = '2024-06-01' +GROUP BY + client, + ecomm +ORDER BY + origins DESC diff --git a/sql/2024/ecommerce/core_web_vitals_yoy.sql b/sql/2024/ecommerce/core_web_vitals_yoy.sql new file mode 100644 index 00000000000..4afe61338ac --- /dev/null +++ b/sql/2024/ecommerce/core_web_vitals_yoy.sql @@ -0,0 +1,193 @@ +# app passing core web vitals +# core_web_vitals_yoy.sql +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 +); + +-- Year 2024 +SELECT + 2024 AS year, + client, + app, + 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 INP divided by origins with any INP. + SAFE_DIVIDE( + COUNT(DISTINCT IF(IS_GOOD(fast_inp, avg_inp, slow_inp), origin, NULL)), + COUNT(DISTINCT IF(IS_NON_ZERO(fast_inp, avg_inp, slow_inp), origin, NULL)) + ) AS pct_good_inp, + + -- 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, INP (optional), and CLS divided by origins with any LCP and CLS. + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(fast_inp, avg_inp, slow_inp) IS NOT FALSE 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(small_cls, medium_cls, large_cls), origin, NULL + )) + ) AS pct_good_cwv +FROM + `chrome-ux-report.materialized.device_summary` +JOIN ( + SELECT + client, + page AS url, + technologies.technology AS app + FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats + WHERE + cats = 'Ecommerce' AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce') AND + technologies.technology != '' AND + date = '2024-06-01' AND + is_root_page +) +ON + CONCAT(origin, '/') = url AND + IF(device = 'desktop', 'desktop', 'mobile') = client +WHERE + date = '2024-06-01' +GROUP BY + client, + app + + +UNION ALL + +-- Year 2023 +SELECT + 2023 AS year, + client, + app, + COUNT(DISTINCT origin) AS origins, + 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, + SAFE_DIVIDE( + COUNT(DISTINCT IF(IS_GOOD(fast_inp, avg_inp, slow_inp), origin, NULL)), + COUNT(DISTINCT IF(IS_NON_ZERO(fast_inp, avg_inp, slow_inp), origin, NULL)) + ) AS pct_good_inp, + 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, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(fast_inp, avg_inp, slow_inp) IS NOT FALSE 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(small_cls, medium_cls, large_cls), origin, NULL + )) + ) AS pct_good_cwv +FROM + `chrome-ux-report.materialized.device_summary` +JOIN ( + SELECT + client, + page AS url, + technologies.technology AS app + FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats + WHERE + cats = 'Ecommerce' AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce') AND + technologies.technology != '' AND + date = '2023-06-01' AND + is_root_page +) +ON + CONCAT(origin, '/') = url AND + IF(device = 'desktop', 'desktop', 'mobile') = client +WHERE + date = '2023-06-01' +GROUP BY + client, + app + +UNION ALL + +-- Year 2022 +SELECT + 2022 AS year, + client, + app, + COUNT(DISTINCT origin) AS origins, + 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, + SAFE_DIVIDE( + COUNT(DISTINCT IF(IS_GOOD(fast_inp, avg_inp, slow_inp), origin, NULL)), + COUNT(DISTINCT IF(IS_NON_ZERO(fast_inp, avg_inp, slow_inp), origin, NULL)) + ) AS pct_good_inp, + 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, + SAFE_DIVIDE( + COUNT(DISTINCT IF( + IS_GOOD(fast_lcp, avg_lcp, slow_lcp) AND + IS_GOOD(fast_inp, avg_inp, slow_inp) IS NOT FALSE 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(small_cls, medium_cls, large_cls), origin, NULL + )) + ) AS pct_good_cwv +FROM + `chrome-ux-report.materialized.device_summary` +JOIN ( + SELECT + client, + page AS url, + technologies.technology AS app + FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats + WHERE + cats = 'Ecommerce' AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce') AND + technologies.technology != '' AND + date = '2022-06-01' AND + is_root_page +) +ON + CONCAT(origin, '/') = url AND + IF(device = 'desktop', 'desktop', 'mobile') = client +WHERE + date = '2022-06-01' +GROUP BY + client, + app + + +ORDER BY + origins DESC diff --git a/sql/2024/ecommerce/median_lighthouse_score_ecommsites.sql b/sql/2024/ecommerce/median_lighthouse_score_ecommsites.sql new file mode 100644 index 00000000000..e899f39f703 --- /dev/null +++ b/sql/2024/ecommerce/median_lighthouse_score_ecommsites.sql @@ -0,0 +1,43 @@ +WITH technologies AS ( + SELECT + client, + page, + category, + technology, + rank, + lighthouse, + COUNT(DISTINCT page) OVER (PARTITION BY client) AS total_websites + FROM `httparchive.all.pages`, + UNNEST(technologies) AS tech, + UNNEST(categories) AS category + WHERE + date = '2024-06-01' AND + is_root_page = TRUE +) + +SELECT + client, + rank, + technology, + ARRAY_AGG(DISTINCT category) AS categories, + APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(lighthouse, '$.categories.performance.score') AS NUMERIC), 1000)[OFFSET(500)] AS median_performance, + APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(lighthouse, '$.categories.accessibility.score') AS NUMERIC), 1000)[OFFSET(500)] AS median_accessibility, + APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(lighthouse, '$.categories.seo.score') AS NUMERIC), 1000)[OFFSET(500)] AS median_seo, + APPROX_QUANTILES(CAST(JSON_EXTRACT_SCALAR(lighthouse, '$.categories.best-practices.score') AS NUMERIC), 1000)[OFFSET(500)] AS median_best_practices, + ANY_VALUE(total_websites) AS total_websites, + COUNT(DISTINCT page) AS number_of_websites, + COUNT(DISTINCT page) / ANY_VALUE(total_websites) AS percent_of_websites +FROM technologies +WHERE + category = 'Ecommerce' AND + ( + technology != 'Cart Functionality' AND + technology != 'Google Analytics Enhanced eCommerce' + ) +GROUP BY + client, + rank, + technology +ORDER BY + client, + number_of_websites DESC diff --git a/sql/2024/ecommerce/top_ecommerce.sql b/sql/2024/ecommerce/top_ecommerce.sql new file mode 100644 index 00000000000..adc2d9987c2 --- /dev/null +++ b/sql/2024/ecommerce/top_ecommerce.sql @@ -0,0 +1,141 @@ +#standardSQL +# Top Ecommerce platforms, compared to until 2021 +# top_ecommerce.sql +SELECT + client, + 2024 AS year, + technologies.technology AS ecommerce, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2024-06-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Ecommerce' AND + date = '2024-06-01' AND + is_root_page AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce') +GROUP BY + client, + total, + ecommerce +UNION ALL +SELECT + client, + 2023 AS year, + technologies.technology AS ecommerce, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2023-06-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Ecommerce' AND + date = '2023-06-01' AND + is_root_page AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce') +GROUP BY + client, + total, + ecommerce +UNION ALL +SELECT + client, + 2022 AS year, + technologies.technology AS ecommerce, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2022-08-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Ecommerce' AND + date = '2022-08-01' AND + is_root_page AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce') +GROUP BY + client, + total, + ecommerce +UNION ALL +SELECT + client, + 2021 AS year, + technologies.technology AS ecommerce, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2021-07-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Ecommerce' AND + date = '2021-07-01' AND + is_root_page AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce') +GROUP BY + client, + total, + ecommerce +ORDER BY + year DESC, + pct DESC diff --git a/sql/2024/ecommerce/top_payment_by_geo.sql b/sql/2024/ecommerce/top_payment_by_geo.sql new file mode 100644 index 00000000000..f93633ad742 --- /dev/null +++ b/sql/2024/ecommerce/top_payment_by_geo.sql @@ -0,0 +1,68 @@ +#standardSQL +# payment popularity per geo +# top_payment_by_geo.sql +WITH geo_summary AS ( + SELECT + `chrome-ux-report`.experimental.GET_COUNTRY(country_code) AS geo, + IF(device = 'desktop', 'desktop', 'mobile') AS client, + origin, + COUNT(DISTINCT origin) OVER (PARTITION BY country_code, IF(device = 'desktop', 'desktop', 'mobile')) AS total + FROM + `chrome-ux-report.materialized.country_summary` + WHERE + yyyymm = 202406 + UNION ALL + SELECT + 'ALL' AS geo, + IF(device = 'desktop', 'desktop', 'mobile') AS client, + origin, + COUNT(DISTINCT origin) OVER (PARTITION BY IF(device = 'desktop', 'desktop', 'mobile')) AS total + FROM + `chrome-ux-report.materialized.device_summary` + WHERE + yyyymm = 202406 +) + +SELECT + * +FROM ( + SELECT + client, + geo, + payment, + COUNT(0) AS pages, + ANY_VALUE(total) AS total, + COUNT(DISTINCT url) / ANY_VALUE(total) AS pct + FROM ( + SELECT DISTINCT + geo, + client, + CONCAT(origin, '/') AS url, + total + FROM + geo_summary + ) JOIN ( + SELECT DISTINCT + client, + cats, + technologies.technology AS payment, + page AS url + FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats + WHERE + technologies.technology IS NOT NULL AND + cats = 'Payment processors' AND + technologies.technology != '' AND + date = '2024-06-01' AND + is_root_page + ) USING (client, url) + GROUP BY + client, + geo, + payment) +WHERE + pages > 1000 +ORDER BY + pages DESC diff --git a/sql/2024/ecommerce/top_payment_yoy.sql b/sql/2024/ecommerce/top_payment_yoy.sql new file mode 100644 index 00000000000..e84fc64a9b5 --- /dev/null +++ b/sql/2024/ecommerce/top_payment_yoy.sql @@ -0,0 +1,137 @@ +#standardSQL +# Top Payment processors platforms, compared to 2021 +# top_payment_yoy.sql +SELECT + client, + 2024 AS year, + technologies.technology AS payment, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2024-06-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Payment processors' AND + date = '2024-06-01' AND + is_root_page +GROUP BY + client, + total, + payment +UNION ALL +SELECT + client, + 2023 AS year, + technologies.technology AS payment, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2023-06-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Payment processors' AND + date = '2023-06-01' AND + is_root_page +GROUP BY + client, + total, + payment +UNION ALL +SELECT + client, + 2022 AS year, + technologies.technology AS payment, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2022-08-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Payment processors' AND + date = '2022-08-01' AND + is_root_page +GROUP BY + client, + total, + payment +UNION ALL +SELECT + client, + 2021 AS year, + technologies.technology AS payment, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2021-07-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Payment processors' AND + date = '2021-07-01' AND + is_root_page +GROUP BY + client, + total, + payment +ORDER BY + year DESC, + pct DESC diff --git a/sql/2024/ecommerce/top_shipping_by_geo.sql b/sql/2024/ecommerce/top_shipping_by_geo.sql new file mode 100644 index 00000000000..c6b90e5d5b5 --- /dev/null +++ b/sql/2024/ecommerce/top_shipping_by_geo.sql @@ -0,0 +1,68 @@ +#standardSQL +# shipping popularity per geo +# top_shipping_by_geo.sql +WITH geo_summary AS ( + SELECT + `chrome-ux-report`.experimental.GET_COUNTRY(country_code) AS geo, + IF(device = 'desktop', 'desktop', 'mobile') AS client, + origin, + COUNT(DISTINCT origin) OVER (PARTITION BY country_code, IF(device = 'desktop', 'desktop', 'mobile')) AS total + FROM + `chrome-ux-report.materialized.country_summary` + WHERE + yyyymm = 202406 + UNION ALL + SELECT + 'ALL' AS geo, + IF(device = 'desktop', 'desktop', 'mobile') AS client, + origin, + COUNT(DISTINCT origin) OVER (PARTITION BY IF(device = 'desktop', 'desktop', 'mobile')) AS total + FROM + `chrome-ux-report.materialized.device_summary` + WHERE + yyyymm = 202406 +) + +SELECT + * +FROM ( + SELECT + client, + geo, + shipping, + COUNT(0) AS pages, + ANY_VALUE(total) AS total, + COUNT(DISTINCT url) / ANY_VALUE(total) AS pct + FROM ( + SELECT DISTINCT + geo, + client, + CONCAT(origin, '/') AS url, + total + FROM + geo_summary + ) JOIN ( + SELECT DISTINCT + client, + cats, + technologies.technology AS shipping, + page AS url + FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats + WHERE + technologies.technology IS NOT NULL AND + cats = 'Shipping carriers' AND + technologies.technology != '' AND + date = '2024-06-01' AND + is_root_page + ) USING (client, url) + GROUP BY + client, + geo, + shipping) +WHERE + pages > 1000 +ORDER BY + pages DESC diff --git a/sql/2024/ecommerce/top_shipping_yoy.sql b/sql/2024/ecommerce/top_shipping_yoy.sql new file mode 100644 index 00000000000..39378ee7c83 --- /dev/null +++ b/sql/2024/ecommerce/top_shipping_yoy.sql @@ -0,0 +1,137 @@ +#standardSQL +# Top Shipping carriers platforms, compared to 2021 +# top_shipping.sql +SELECT + client, + 2024 AS year, + technologies.technology AS shipping, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2024-06-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Shipping carriers' AND + date = '2024-06-01' AND + is_root_page +GROUP BY + client, + total, + shipping +UNION ALL +SELECT + client, + 2023 AS year, + technologies.technology AS shipping, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2023-06-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Shipping carriers' AND + date = '2023-06-01' AND + is_root_page +GROUP BY + client, + total, + shipping +UNION ALL +SELECT + client, + 2022 AS year, + technologies.technology AS shipping, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2022-08-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Shipping carriers' AND + date = '2022-08-01' AND + is_root_page +GROUP BY + client, + total, + shipping +UNION ALL +SELECT + client, + 2021 AS year, + technologies.technology AS shipping, + COUNT(DISTINCT page) AS freq, + total, + COUNT(DISTINCT page) / total AS pct +FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats +JOIN ( + SELECT + client, + COUNT(0) AS total + FROM + `httparchive.all.pages` + WHERE + date = '2021-07-01' AND + is_root_page + GROUP BY + client) +USING + (client) +WHERE + cats = 'Shipping carriers' AND + date = '2021-07-01' AND + is_root_page +GROUP BY + client, + total, + shipping +ORDER BY + year DESC, + pct DESC diff --git a/sql/2024/ecommerce/top_shopsystem_by_geo.sql b/sql/2024/ecommerce/top_shopsystem_by_geo.sql new file mode 100644 index 00000000000..b1fec4802a2 --- /dev/null +++ b/sql/2024/ecommerce/top_shopsystem_by_geo.sql @@ -0,0 +1,70 @@ +#standardSQL +# Shopsystem popularity per geo +# top_shopsystem_by_geo.sql +WITH geo_summary AS ( + SELECT + `chrome-ux-report`.experimental.GET_COUNTRY(country_code) AS geo, + IF(device = 'desktop', 'desktop', 'mobile') AS client, + origin, + COUNT(DISTINCT origin) OVER (PARTITION BY country_code, IF(device = 'desktop', 'desktop', 'mobile')) AS total + FROM + `chrome-ux-report.materialized.country_summary` + WHERE + yyyymm = 202406 + UNION ALL + SELECT + 'ALL' AS geo, + IF(device = 'desktop', 'desktop', 'mobile') AS client, + origin, + COUNT(DISTINCT origin) OVER (PARTITION BY IF(device = 'desktop', 'desktop', 'mobile')) AS total + FROM + `chrome-ux-report.materialized.device_summary` + WHERE + yyyymm = 202406 +) + +SELECT + * +FROM ( + SELECT + client, + geo, + app, + COUNT(0) AS pages, + ANY_VALUE(total) AS total, + COUNT(DISTINCT url) / ANY_VALUE(total) AS pct + FROM ( + SELECT DISTINCT + geo, + client, + CONCAT(origin, '/') AS url, + total + FROM + geo_summary + ) JOIN ( + SELECT DISTINCT + client, + cats, + technologies.technology AS app, + page AS url + FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats + WHERE + technologies.technology IS NOT NULL AND + cats = 'Ecommerce' AND + technologies.technology != 'Cart Functionality' AND + technologies.technology != 'Google Analytics Enhanced eCommerce' AND + technologies.technology != '' AND + date = '2024-06-01' AND + is_root_page + ) USING (client, url) + GROUP BY + client, + geo, + app) +WHERE + pages > 1000 +ORDER BY + pages DESC diff --git a/sql/2024/ecommerce/top_vendors_crux_rank.sql b/sql/2024/ecommerce/top_vendors_crux_rank.sql new file mode 100644 index 00000000000..410d1010460 --- /dev/null +++ b/sql/2024/ecommerce/top_vendors_crux_rank.sql @@ -0,0 +1,63 @@ +#standardSQL +# Ecommerce adoption per rank +# top_ecommerce_by_rank.sql + +SELECT + client, + ecommerce, + rank, + COUNT(DISTINCT url) AS pages, + ANY_VALUE(total) AS total, + COUNT(DISTINCT url) / ANY_VALUE(total) AS pct +FROM ( + SELECT DISTINCT + client, + page AS url, + technologies.technology AS ecommerce + FROM + `httparchive.all.pages`, + UNNEST(technologies) AS technologies, + UNNEST(technologies.categories) AS cats + WHERE + cats = 'Ecommerce' AND + date = '2024-06-01' AND + is_root_page AND + technologies.technology NOT IN ('Cart Functionality', 'Google Analytics Enhanced eCommerce')) +JOIN ( + SELECT + client, + page AS url, + rank_magnitude AS rank + FROM + `httparchive.all.pages`, + UNNEST([1e3, 1e4, 1e5, 1e6, 1e7]) AS rank_magnitude + WHERE + rank <= rank_magnitude AND + date = '2024-06-01' AND + is_root_page) +USING + (client, url) +JOIN ( + SELECT + client, + rank_magnitude AS rank, + COUNT(0) AS total + FROM + `httparchive.all.pages`, + UNNEST([1e3, 1e4, 1e5, 1e6, 1e7]) AS rank_magnitude + WHERE + rank <= rank_magnitude AND + date = '2024-06-01' AND + is_root_page + GROUP BY + client, + rank_magnitude) +USING + (client, rank) +GROUP BY + client, + ecommerce, + rank +ORDER BY + rank, + pages DESC