Las consultas de ejemplo que aparecen en esta página se aplican a los datos de usuario de Google Analytics 4 exportados a BigQuery. La exportación de datos de usuario a BigQuery crea dos tablas de cada día:
users_YYYYMMDD
: contiene una fila por cada ID de usuario que haya cambiado.pseudonymous_users_YYYYMMDD
: contiene una fila por cada identificador seudónimo que haya cambiado.
Consulta el esquema de datos de usuario de BigQuery Export para obtener más información.
Consultar datos de un periodo concreto
Para consultar un conjunto de datos de usuario exportados a BigQuery de un periodo específico, usa la pseudocolumna _TABLE_SUFFIX
en la cláusula WHERE
de la consulta.
Por ejemplo, la siguiente consulta devuelve el recuento de usuarios únicos actualizados entre el 1 y el 15 de agosto del 2023 cuya duración de la interacción en el tiempo de vida fue de al menos 5 minutos.
users
-- Example: Query a specific date range for users meeting a lifetime engagement criterion.
--
-- Counts unique users that are in the BigQuery user-data exports for a specific date range and have
-- a lifetime engagement of 5 minutes or more.
SELECT
COUNT(DISTINCT user_id) AS user_count
FROM
-- Uses a table suffix wildcard to define the set of daily tables to query.
`PROJECT_ID.analytics_PROPERTY_ID.users_202308*`
WHERE
-- Filters to users updated between August 1 and August 15.
_TABLE_SUFFIX BETWEEN '01' AND '15'
-- Filters by users who have a lifetime engagement of 5 minutes or more.
AND user_ltv.engagement_time_millis >= 5 * 60 * 1000;
pseudonymous_users
-- Example: Query a specific date range for users meeting a lifetime engagement criterion.
--
-- Counts unique pseudonymous users that are in the BigQuery user-data exports for a specific date
-- range and have a lifetime engagement of 5 minutes or more.
SELECT
COUNT(DISTINCT pseudo_user_id) AS pseudo_user_count
FROM
-- Uses a table suffix wildcard to define the set of daily tables to query.
`PROJECT_ID.analytics_PROPERTY_ID.pseudonymous_users_202308*`
WHERE
-- Filters to users updated between August 1 and August 15.
_TABLE_SUFFIX BETWEEN '01' AND '15'
-- Filters by users who have a lifetime engagement of 5 minutes or more.
AND user_ltv.engagement_time_millis >= 5 * 60 * 1000;
En cada ejemplo, se delimita el conjunto de datos del 1 al 15 de agosto del 2023 de dos maneras:
- Usando el comodín
202308*
en la cláusulaFROM
. - Usando la condición
_TABLE_SUFFIX
en la cláusulaWHERE
, que filtra las tablas según la posición del comodín en el nombre de tabla. En202308*
, el comodín sustituye al día del mes.
Puedes aplicar un procedimiento similar para consultar los datos de varios meses. Por ejemplo, para consultar los datos del periodo comprendido entre enero y octubre del 2023, adapta la consulta para que incluya lo siguiente:
- El comodín
2023*
. - Esta condición de tipo
_TABLE_SUFFIX
:_TABLE_SUFFIX BETWEEN '0101' AND '1031'
.
También puedes consultar los datos de varios años. Por ejemplo, para consultar los datos del periodo comprendido entre octubre del 2022 y febrero del 2023, adapta la consulta para que incluya lo siguiente:
- El comodín
202*
. - Esta condición de tipo
_TABLE_SUFFIX
:_TABLE_SUFFIX BETWEEN '21001' AND '30331'
.
IDs de usuarios de los que ha cambiado una propiedad recientemente
La siguiente consulta devuelve el valor de user_id
y pseudo_user_id
de todos los usuarios de los que ha cambiado una propiedad específica hace poco.
users
-- Example: Get the list of user_ids with recent changes to a specific user property.
DECLARE
UPDATE_LOWER_BOUND_MICROS INT64;
-- Replace timezone. List at https://en.wikipedia.org/wiki/List_of_tz_database_time_zones.
DECLARE
REPORTING_TIMEZONE STRING DEFAULT 'America/Los_Angeles';
-- Sets the variable for the earliest update time to include. This comes after setting
-- the REPORTING_TIMEZONE so this expression can use that variable.
SET UPDATE_LOWER_BOUND_MICROS = UNIX_MICROS(
TIMESTAMP_SUB(
TIMESTAMP_TRUNC(CURRENT_TIMESTAMP(), DAY, REPORTING_TIMEZONE),
INTERVAL 14 DAY));
-- Selects users with changes to a specific user property since the lower bound.
SELECT
users.user_id,
FORMAT_TIMESTAMP('%F %T',
TIMESTAMP_MICROS(
MAX(properties.value.set_timestamp_micros)),
REPORTING_TIMEZONE) AS max_set_timestamp
FROM
-- Uses a table prefix to scan all data for 2023. Update the prefix as needed to query a different
-- date range.
`PROJECT_ID.analytics_PROPERTY_ID.users_2023*` AS users,
users.user_properties properties
WHERE
properties.value.user_property_name = 'job_function'
AND properties.value.set_timestamp_micros >= UPDATE_LOWER_BOUND_MICROS
GROUP BY
1;
pseudonymous_users
-- Example: Get the list of pseudo_user_ids with recent changes to a specific user property.
DECLARE
UPDATE_LOWER_BOUND_MICROS INT64;
-- Replace timezone. List at https://en.wikipedia.org/wiki/List_of_tz_database_time_zones.
DECLARE
REPORTING_TIMEZONE STRING DEFAULT 'America/Los_Angeles';
-- Sets the variable for the earliest update time to include. This comes after setting
-- the REPORTING_TIMEZONE so this expression can use that variable.
SET UPDATE_LOWER_BOUND_MICROS = UNIX_MICROS(
TIMESTAMP_SUB(
TIMESTAMP_TRUNC(CURRENT_TIMESTAMP(), DAY, REPORTING_TIMEZONE),
INTERVAL 14 DAY));
-- Selects users with changes to a specific user property since the lower bound.
SELECT
users.pseudo_user_id,
FORMAT_TIMESTAMP('%F %T',
TIMESTAMP_MICROS(
MAX(properties.value.set_timestamp_micros)),
REPORTING_TIMEZONE) AS max_set_timestamp
FROM
-- Uses a table prefix to scan all data for 2023. Update the prefix as needed to query a different
-- date range.
`PROJECT_ID.analytics_PROPERTY_ID.pseudonymous_users_2023*` AS users,
users.user_properties properties
WHERE
properties.value.user_property_name = 'job_function'
AND properties.value.set_timestamp_micros >= UPDATE_LOWER_BOUND_MICROS
GROUP BY
1;
Resumen de novedades
Usa esta consulta para saber por qué el conjunto de datos de usuario exportados incluye o excluye usuarios de distintas categorías.
users
-- Summarizes data by change type.
-- Defines the export date to query. This must match the table suffix in the FROM
-- clause below.
DECLARE EXPORT_DATE DATE DEFAULT DATE(2023,6,16);
-- Creates a temporary function that will return true if a timestamp (in micros) is for the same
-- date as the specified day value.
CREATE TEMP FUNCTION WithinDay(ts_micros INT64, day_value DATE)
AS (
(ts_micros IS NOT NULL) AND
-- Change the timezone to your property's reporting time zone.
-- List at https://en.wikipedia.org/wiki/List_of_tz_database_time_zones.
(DATE(TIMESTAMP_MICROS(ts_micros), 'America/Los_Angeles') = day_value)
);
-- Creates a temporary function that will return true if a date string in 'YYYYMMDD' format is
-- for the same date as the specified day value.
CREATE TEMP FUNCTION SameDate(date_string STRING, day_value DATE)
AS (
(date_string IS NOT NULL) AND
(PARSE_DATE('%Y%m%d', date_string) = day_value)
);
WITH change_types AS (
SELECT user_id,
WithinDay(user_info.last_active_timestamp_micros, EXPORT_DATE) AS user_activity,
WithinDay(user_info.user_first_touch_timestamp_micros, EXPORT_DATE) AS first_touch,
SameDate(user_info.first_purchase_date, EXPORT_DATE) as first_purchase,
(EXISTS (SELECT 1 FROM UNNEST(audiences) AS aud
WHERE WithinDay(aud.membership_start_timestamp_micros, EXPORT_DATE))) AS audience_add,
(EXISTS (SELECT 1 FROM UNNEST(audiences) AS aud
WHERE WithinDay(aud.membership_expiry_timestamp_micros, EXPORT_DATE))) AS audience_remove,
(EXISTS (SELECT 1 FROM UNNEST(user_properties) AS prop
WHERE WithinDay(prop.value.set_timestamp_micros, EXPORT_DATE))) AS user_property_change
FROM
-- The table suffix must match the date used to define EXPORT_DATE above.
`project_id.analytics_property_id.users_20230616`
)
SELECT
user_activity,
first_touch,
first_purchase,
audience_add,
audience_remove,
user_property_change,
-- This field will be true if there are no changes for the other change types.
NOT (user_activity OR first_touch OR audience_add OR audience_remove OR user_property_change) AS other_change,
COUNT(DISTINCT user_id) AS user_id_count
FROM change_types
GROUP BY 1,2,3,4,5,6,7;
pseudonymous_users
-- Summarizes data by change type.
-- Defines the export date to query. This must match the table suffix in the FROM
-- clause below.
DECLARE EXPORT_DATE DATE DEFAULT DATE(2023,6,16);
-- Creates a temporary function that will return true if a timestamp (in micros) is for the same
-- date as the specified day value.
CREATE TEMP FUNCTION WithinDay(ts_micros INT64, day_value DATE)
AS (
(ts_micros IS NOT NULL) AND
-- Change the timezone to your property's reporting time zone.
-- List at https://en.wikipedia.org/wiki/List_of_tz_database_time_zones.
(DATE(TIMESTAMP_MICROS(ts_micros), 'America/Los_Angeles') = day_value)
);
-- Creates a temporary function that will return true if a date string in 'YYYYMMDD' format is
-- for the same date as the specified day value.
CREATE TEMP FUNCTION SameDate(date_string STRING, day_value DATE)
AS (
(date_string IS NOT NULL) AND
(PARSE_DATE('%Y%m%d', date_string) = day_value)
);
WITH change_types AS (
SELECT pseudo_user_id,
WithinDay(user_info.last_active_timestamp_micros, EXPORT_DATE) AS user_activity,
WithinDay(user_info.user_first_touch_timestamp_micros, EXPORT_DATE) AS first_touch,
SameDate(user_info.first_purchase_date, EXPORT_DATE) as first_purchase,
(EXISTS (SELECT 1 FROM UNNEST(audiences) AS aud
WHERE WithinDay(aud.membership_start_timestamp_micros, EXPORT_DATE))) AS audience_add,
(EXISTS (SELECT 1 FROM UNNEST(audiences) AS aud
WHERE WithinDay(aud.membership_expiry_timestamp_micros, EXPORT_DATE))) AS audience_remove,
(EXISTS (SELECT 1 FROM UNNEST(user_properties) AS prop
WHERE WithinDay(prop.value.set_timestamp_micros, EXPORT_DATE))) AS user_property_change
FROM
-- The table suffix must match the date used to define EXPORT_DATE above.
`PROJECT_ID.analytics_PROPERTY_ID.pseudonymous_users_20230616`
)
SELECT
user_activity,
first_touch,
first_purchase,
audience_add,
audience_remove,
user_property_change,
-- This field will be true if there are no changes for the other change types.
NOT (user_activity OR first_touch OR audience_add OR audience_remove OR user_property_change) AS other_change,
COUNT(DISTINCT pseudo_user_id) pseudo_user_id_count
FROM change_types
GROUP BY 1,2,3,4,5,6,7;