Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Mobile Web 2021 queries #2310

Merged
merged 24 commits into from
Oct 15, 2021
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
24 commits
Select commit Hold shift + click to select a range
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
62 changes: 62 additions & 0 deletions sql/2021/mobile-web/client_hints.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
# standardSQL
# Usage of client hint directives
CREATE TEMPORARY FUNCTION getClientHints(headers STRING)
RETURNS ARRAY<STRING> LANGUAGE js AS """
try {
const header_name = 'Accept-CH';
const parsed_headers = JSON.parse(headers);
const matching_headers = parsed_headers.filter(h => h.name.toLowerCase() == header_name.toLowerCase());
if (matching_headers.length <= 0) {
return [];
}

const unique_directives = new Set();
for (const header of matching_headers) {
const directives = header.value.split(/\\s*,\\s*/);
for (const directive of directives) {
unique_directives.add(directive);
}
}

return Array.from(unique_directives);
} catch (e) {
return [];
}
""";

SELECT
client,
total_pages,
SUM(COUNT(DISTINCT page)) OVER (PARTITION BY client) AS total_pages_using_ch,

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Nit remove blank line

Suggested change

ch_directive,
COUNT(0) AS total_pages_using,
COUNT(0) / total_pages AS pct_pages,
COUNT(0) / SUM(COUNT(DISTINCT page)) OVER (PARTITION BY client) AS pct_ch_pages_using
FROM (
SELECT
page,
client,
ch_directive
FROM
`httparchive.almanac.requests`,
UNNEST(getClientHints(JSON_EXTRACT(payload, '$.response.headers'))) AS ch_directive
WHERE
date = "2021-07-01" AND
firstHtml
)
LEFT JOIN (
SELECT
_TABLE_SUFFIX AS client,
COUNT(0) AS total_pages
FROM
`httparchive.pages.2021_07_01_*`
GROUP BY _TABLE_SUFFIX
)
USING (client)
GROUP BY
client,
ch_directive,
total_pages
ORDER BY
pct_pages DESC
12 changes: 12 additions & 0 deletions sql/2021/mobile-web/color_contrast.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
#standardSQL
# % mobile pages with sufficient text color contrast with its background
SELECT
COUNTIF(color_contrast_score IS NOT NULL) AS total_applicable,
COUNTIF(CAST(color_contrast_score AS NUMERIC) = 1) AS total_sufficient,
COUNTIF(CAST(color_contrast_score AS NUMERIC) = 1) / COUNTIF(color_contrast_score IS NOT NULL) AS pct_in_applicable
FROM (
SELECT
JSON_EXTRACT_SCALAR(report, '$.audits.color-contrast.score') AS color_contrast_score
FROM
`httparchive.lighthouse.2021_07_01_mobile`
)
12 changes: 12 additions & 0 deletions sql/2021/mobile-web/correctly_sized_images.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
#standardSQL
# pages with perfect scores on the properly sized images audit
SELECT
COUNTIF(properly_sized_images_score IS NOT NULL) AS total_applicable,
COUNTIF(properly_sized_images_score = 1) AS total_with_properly_sized_images,
COUNTIF(properly_sized_images_score = 1) / COUNTIF(properly_sized_images_score IS NOT NULL) AS pct_with_properly_sized_images
FROM (
SELECT
SAFE_CAST(JSON_EXTRACT_SCALAR(report, '$.audits.uses-responsive-images.score') AS NUMERIC) AS properly_sized_images_score
FROM
`httparchive.lighthouse.2021_07_01_mobile`
)
13 changes: 13 additions & 0 deletions sql/2021/mobile-web/credential_management_api_usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
#standardSQL
# Usage of Credential Manager
SELECT DISTINCT
client,
feature,
num_urls AS freq,
total_urls AS total,
pct_urls AS pct
FROM
`httparchive.blink_features.usage`
WHERE
yyyymmdd = '20210701' AND
feature = 'CredentialManagerGet'
50 changes: 50 additions & 0 deletions sql/2021/mobile-web/ecommerce_with_type_search.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@
#standardSQL
# Ecommerce pages using type=search inputs
CREATE TEMPORARY FUNCTION getSearchInputStats(payload STRING)
RETURNS STRUCT<has_inputs BOOLEAN, has_search_inputs BOOLEAN> LANGUAGE js AS '''
try {
const almanac = JSON.parse(payload);
const search_node_index = almanac.input_elements.nodes.findIndex((node) => {
return node.type.toLowerCase() === 'search';
});

return {
has_inputs: almanac.input_elements.total > 0,
has_search_inputs: search_node_index >= 0,
};
} catch (e) {
return {
has_inputs: false,
has_search_inputs: false,
};
}
''';

SELECT
client,
COUNT(0) AS total_pages,
COUNTIF(search_input_stats.has_inputs) AS pages_with_inputs,
COUNTIF(search_input_stats.has_search_inputs) AS pages_with_search_inputs,

COUNTIF(search_input_stats.has_search_inputs) / COUNT(0) AS pct_pages_with_search_inputs,
COUNTIF(search_input_stats.has_search_inputs) / COUNTIF(search_input_stats.has_inputs) AS pct_input_pages_with_search_inputs
FROM (
SELECT
_TABLE_SUFFIX AS client,
getSearchInputStats(JSON_EXTRACT_SCALAR(payload, '$._almanac')) AS search_input_stats,
url
FROM
`httparchive.pages.2021_07_01_*`
)
JOIN (
SELECT
_TABLE_SUFFIX AS client,
url
FROM
`httparchive.technologies.2021_07_01_*`
WHERE
category = 'Ecommerce'
)
USING (client, url)
GROUP BY
client
21 changes: 21 additions & 0 deletions sql/2021/mobile-web/ect_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
#standardSQL
# ECT distribution
SELECT
device,
percentile,
APPROX_QUANTILES(_4GDensity / (_4GDensity + _3GDensity + _2GDensity + slow2GDensity + offlineDensity), 1000)[OFFSET(percentile * 10)] AS _4GDensity,
APPROX_QUANTILES(_3GDensity / (_4GDensity + _3GDensity + _2GDensity + slow2GDensity + offlineDensity), 1000)[OFFSET(percentile * 10)] AS _3GDensity,
APPROX_QUANTILES(_2GDensity / (_4GDensity + _3GDensity + _2GDensity + slow2GDensity + offlineDensity), 1000)[OFFSET(percentile * 10)] AS _2GDensity,
APPROX_QUANTILES(slow2GDensity / (_4GDensity + _3GDensity + _2GDensity + slow2GDensity + offlineDensity), 1000)[OFFSET(percentile * 10)] AS slow2GDensity,
APPROX_QUANTILES(offlineDensity / (_4GDensity + _3GDensity + _2GDensity + slow2GDensity + offlineDensity), 1000)[OFFSET(percentile * 10)] AS offlineDensity
FROM
`chrome-ux-report.materialized.device_summary`,
UNNEST(GENERATE_ARRAY(1, 100)) AS percentile
WHERE
date = '2021-07-01'
GROUP BY
device,
percentile
ORDER BY
device,
percentile
Comment on lines +1 to +21
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I ran this query and getting very weird results, where the top percentiles (90-100) for 3G are offsetting the bottom percentiles (1-10) for 4G. Not sure if it's the best way of presenting this data?

Also we don't traditionally report tablet. Though maybe it makes more sense for this chapter?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

We ran into the same problem last year and ended up scrapping it because of how confusing it was to present (can see the comment thread here)

We ideally wanted to find the split of 3g and 4g usage on websites, but aggregating that data across all websites still proves challenging

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Could you just do them as separate queries looking at only one each time? Might be less confusing then as no offsetting.

36 changes: 36 additions & 0 deletions sql/2021/mobile-web/lazy_loading_usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
#standardSQL
# Usage of native lazy loading
CREATE TEMPORARY FUNCTION usesLoadingLazy(payload STRING)
RETURNS BOOLEAN LANGUAGE js AS '''
try {
const almanac = JSON.parse(payload);

let found = false;
for (const node of almanac.images.imgs.nodes) {
if (node.loading === "lazy") {
found = true;
break;
}
}

return found;
} catch (e) {
return false;
}
''';
SELECT
client,
COUNTIF(total_img > 0) AS pages_with_images,

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Suggested change

COUNTIF(uses_loading_lazy) AS pages_using_loading_attribute,
COUNTIF(uses_loading_lazy) / COUNTIF(total_img > 0) AS pct_pages_using_loading_attribute
FROM (
SELECT
_TABLE_SUFFIX AS client,
SAFE_CAST(JSON_EXTRACT_SCALAR(JSON_EXTRACT_SCALAR(payload, '$._almanac'), '$.images.imgs.total') AS INT64) AS total_img,
usesLoadingLazy(JSON_EXTRACT_SCALAR(payload, '$._almanac')) AS uses_loading_lazy
FROM
`httparchive.pages.2021_07_01_*`
)
GROUP BY
client
15 changes: 15 additions & 0 deletions sql/2021/mobile-web/mobile_traffic_distribution.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
#standardSQL
# Distribution of traffic coming from mobile devices
SELECT
percentile,
APPROX_QUANTILES(phoneDensity, 1000)[OFFSET(percentile * 10)] AS pct_traffic_from_mobile
FROM
`chrome-ux-report.materialized.device_summary`,
UNNEST(GENERATE_ARRAY(1, 100)) AS percentile
WHERE
date = '2021-07-01' AND
device = 'phone'
GROUP BY
percentile
ORDER BY
percentile
23 changes: 23 additions & 0 deletions sql/2021/mobile-web/most_used_tech.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
#standardSQL
# Most used technologies - mobile only
SELECT
total_pages,

category,
app,
COUNT(0) AS pages_with_app,
COUNT(0) / total_pages AS pct_pages_with_app
FROM
`httparchive.technologies.2021_07_01_mobile`
CROSS JOIN (
SELECT
COUNT(0) AS total_pages
FROM
`httparchive.summary_pages.2021_07_01_mobile`
)
GROUP BY
total_pages,
category,
app
ORDER BY
pct_pages_with_app DESC
48 changes: 48 additions & 0 deletions sql/2021/mobile-web/most_used_tech_by_domain_rank.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
#standardSQL
# Most used technologies by domain rank - mobile only
SELECT
rank_grouping,
total_in_rank,

category,
app,
COUNT(0) AS pages_with_app,
COUNT(0) / total_in_rank AS pct_pages_with_app
FROM (
SELECT
app,
category,
url
FROM
`httparchive.technologies.2021_07_01_mobile`
)
LEFT OUTER JOIN (
SELECT
url,
rank_grouping
FROM
`httparchive.summary_pages.2021_07_01_mobile`,
UNNEST([1000, 10000, 100000, 1000000, 10000000]) AS rank_grouping
WHERE
rank <= rank_grouping
) USING (url)
JOIN (
SELECT
rank_grouping,
COUNT(0) AS total_in_rank
FROM
`httparchive.summary_pages.2021_07_01_mobile`,
UNNEST([1000, 10000, 100000, 1000000, 10000000]) AS rank_grouping
WHERE
rank <= rank_grouping
GROUP BY
rank_grouping
) USING (rank_grouping)
GROUP BY
rank_grouping,
total_in_rank,
category,
app
ORDER BY
app,
rank_grouping
13 changes: 13 additions & 0 deletions sql/2021/mobile-web/navigator_device_memory_usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
#standardSQL
# Usage of Navigator.deviceMemory
SELECT
client,
feature,
num_urls AS freq,
total_urls AS total,
pct_urls AS pct
FROM
`httparchive.blink_features.usage`
WHERE
yyyymmdd = '20210701' AND
feature = 'NavigatorDeviceMemory'
13 changes: 13 additions & 0 deletions sql/2021/mobile-web/network_info_effective_type_usage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
#standardSQL
# Usage of NetworkInformation.effectiveType
SELECT
client,
feature,
num_urls AS freq,
total_urls AS total,
pct_urls AS pct
FROM
`httparchive.blink_features.usage`
WHERE
yyyymmdd = '20210701' AND
feature = 'NetInfoEffectiveType'
Loading