Skip to content

Instantly share code, notes, and snippets.

@rviscomi
Created April 28, 2023 18:52
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save rviscomi/b930b1bffcef6ef6e9fb662ca5fbb56c to your computer and use it in GitHub Desktop.
Save rviscomi/b930b1bffcef6ef6e9fb662ca5fbb56c to your computer and use it in GitHub Desktop.
Create a BigQuery view to summarize the Web Vitals data from GA and a helper function for restricting the date range
CREATE OR REPLACE VIEW httparchive.analytics_373060815.web_vitals AS (
SELECT
event_name AS metric_name,
* EXCEPT(event_name, is_last_received_value)
FROM (
SELECT
*,
REGEXP_SUBSTR((SELECT value.string_value FROM UNNEST(event_params) WHERE key = 'page_location'), r'\/\/.*?(\/[^?]*)') AS page_path,
ROUND((SELECT COALESCE(value.double_value, value.int_value) FROM UNNEST(event_params) WHERE key = 'value'), 3) AS metric_value,
IF (ROW_NUMBER() OVER (PARTITION BY (
SELECT
value.string_value
FROM
UNNEST(event_params)
WHERE
key = 'event_label'
) ORDER BY (
SELECT
COALESCE(value.double_value, value.int_value)
FROM
UNNEST(event_params)
WHERE
key = 'value'
) DESC ) = 1, TRUE, FALSE) AS is_last_received_value
FROM
`httparchive.analytics_373060815.events_intraday_*`
WHERE
event_name IN ('CLS', 'FID', 'LCP', 'INP', 'FCP', 'TTFB')
)
WHERE
is_last_received_value
);
CREATE OR REPLACE FUNCTION httparchive.analytics_373060815.FILTER_PREVIOUS_N_DAYS(dateStr STRING, n INT64, include_today BOOL) RETURNS BOOL AS (
dateStr BETWEEN
FORMAT_DATE('%Y%m%d', DATE_SUB(CURRENT_DATE, INTERVAL n DAY))
AND
FORMAT_DATE('%Y%m%d', DATE_SUB(CURRENT_DATE, INTERVAL IF(include_today, 0, 1) DAY))
);
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment