diff --git a/GRAVEYARD.md b/GRAVEYARD.md index 6346f855e08..d5d4f9fa431 100644 --- a/GRAVEYARD.md +++ b/GRAVEYARD.md @@ -2,9 +2,17 @@ This document records interesting code that we've deleted for the sake of discoverability for the future. +## 2021-08 Remove amplitude views + +- [Removal PR](https://github.com/mozilla/bigquery-etl/pull/2279) +- [DAG removal PR](https://github.com/mozilla/telemetry-airflow/pull/1328) + +We no longer send data to Amplitude, so these views and scripts were +no longer being used. + ## 2021-05 attitudes_daily -- [Removal PR](https://github.com/mozilla/bigquery-etl/pull/2003); +- [Removal PR](https://github.com/mozilla/bigquery-etl/pull/2003) - [DAG removal PR](https://github.com/mozilla/telemetry-airflow/pull/1299) - [Bug 1707965](https://bugzilla.mozilla.org/show_bug.cgi?id=) diff --git a/bigquery_etl/shredder/amplitude.py b/bigquery_etl/shredder/amplitude.py deleted file mode 100644 index 540779bc76f..00000000000 --- a/bigquery_etl/shredder/amplitude.py +++ /dev/null @@ -1,148 +0,0 @@ -"""Forward deletion requests from BigQuery to Amplitude.""" - -import json -import logging -import warnings -from argparse import ArgumentParser -from datetime import datetime -from multiprocessing.pool import ThreadPool -from os import environ -from time import sleep, time - -import requests -from google.cloud import bigquery -from requests.adapters import HTTPAdapter -from urllib3.util.retry import Retry - -from ..util import standard_args - -AMPLITUDE_API_KEY = "AMPLITUDE_API_KEY" -AMPLITUDE_SECRET_KEY = "AMPLITUDE_SECRET_KEY" - -parser = ArgumentParser(description=__doc__) -standard_args.add_argument( - parser, - "--date", - type=lambda d: datetime.strptime(d, "%Y-%m-%d").date(), - required=True, - help="Deletion request date to forward to amplitude", -) -standard_args.add_argument( - parser, - "--table-id", - "--table_id", - required=True, - help="Deletion request table to forward to amplitude", -) - -group = parser.add_mutually_exclusive_group(required=True) -standard_args.add_argument( - group, - "--user-id-field", - "--user_id_field", - help="Field in --table-id that maps to user_id in amplitude", -) -standard_args.add_argument( - group, - "--device-id-field", - "--device_id_field", - help="Field in --table-id that maps to device_id in amplitude;" - " Do not use unless --user-id-field isn't available", -) - -standard_args.add_argument( - parser, - "--api-key", - "--api_key", - default=environ.get(AMPLITUDE_API_KEY), - required=AMPLITUDE_API_KEY not in environ, - help="Amplitude API key; used for identify and deletions api calls", -) -standard_args.add_argument( - parser, - "--secret-key", - "--secret_key", - default=environ.get(AMPLITUDE_SECRET_KEY), - required=AMPLITUDE_SECRET_KEY not in environ, - help="Amplitude secret key; used for deletions api calls", -) -standard_args.add_log_level(parser) - - -def main(): - """Read deletion requests from bigquery and send them to amplitude.""" - args = parser.parse_args() - - requests_session = requests.Session() - requests_session.mount( - "https://", - HTTPAdapter( - max_retries=Retry( - total=3, - status_forcelist=[429, 500, 502, 503, 504], - method_whitelist=["POST"], - ) - ), - ) - - ids = [ - row[0] - for row in bigquery.Client().query( - f"SELECT {args.user_id_field or args.device_id_field} FROM {args.table_id}" - f" WHERE DATE(submission_timestamp) = DATE '{args.date}'" - ) - ] - - # associate device_ids to matching user_ids so that they can be deleted - if args.user_id_field is None: - identify_parallelism, identify_batch_size = 100, 10 - - def _identify(start): - # this api is limited to 100 batches per second, so don't return any faster - # https://help.amplitude.com/hc/en-us/articles/360032842391-HTTP-API-V2#upload-limit - earliest_return = time() + identify_parallelism / 100 - end = start + identify_batch_size - requests_session.post( - "https://api2.amplitude.com/identify", - data={ - "api_key": args.api_key, - "identification": json.dumps( - [{"device_id": id, "user_id": id} for id in ids[start:end]] - ), - }, - ).raise_for_status() - # sleep to match api speed limit if necessary - sleep(max(0, earliest_return - time())) - - with ThreadPool(identify_parallelism) as pool: - logging.info("Identifying relevant device_ids as user_ids") - pool.map(_identify, range(0, len(ids), identify_batch_size), chunksize=1) - - deletions_parallelism, deletions_batch_size = 1, 100 - - def _deletions(start): - # this api is limited to 1 batch per second, so don't return any faster - # https://help.amplitude.com/hc/en-us/articles/360000398191-User-Privacy-API#h_2beded8a-5c39-4113-a847-551b7151339b - earliest_return = time() + deletions_parallelism - end = start + deletions_batch_size - requests_session.post( - "https://amplitude.com/api/2/deletions/users", - auth=(args.api_key, args.secret_key), - json={ - "user_ids": ids[start:end], - "requester": "shredder", - "ignore_invalid_id": "True", - "delete_from_org": "False", - }, - ).raise_for_status() - # sleep to match api speed limit if necessary - sleep(max(0, earliest_return - time())) - - with ThreadPool(deletions_parallelism) as pool: - logging.info("Submitting deletions") - pool.map(_deletions, range(0, len(ids), deletions_batch_size), chunksize=1) - - -if __name__ == "__main__": - warnings.filterwarnings("ignore", module="google.auth._default") - main() diff --git a/script/shredder_amplitude b/script/shredder_amplitude deleted file mode 100755 index 22d2b7ee660..00000000000 --- a/script/shredder_amplitude +++ /dev/null @@ -1,5 +0,0 @@ -#!/bin/sh - -cd "$(dirname "$0")/.." - -exec python3 -m bigquery_etl.shredder.amplitude "$@" diff --git a/sql/moz-fx-data-shared-prod/firefox_accounts/fxa_amplitude_export/view.sql b/sql/moz-fx-data-shared-prod/firefox_accounts/fxa_amplitude_export/view.sql deleted file mode 100644 index 78076c2499b..00000000000 --- a/sql/moz-fx-data-shared-prod/firefox_accounts/fxa_amplitude_export/view.sql +++ /dev/null @@ -1,138 +0,0 @@ -CREATE OR REPLACE VIEW - `moz-fx-data-shared-prod.firefox_accounts.fxa_amplitude_export` -AS -WITH active_users AS ( - SELECT - TIMESTAMP(submission_date_pacific, "America/Los_Angeles") AS submission_timestamp, - `moz-fx-data-shared-prod`.udf.active_values_from_days_seen_map( - os_used_month, - 0, - 1 - ) AS os_used_day, - `moz-fx-data-shared-prod`.udf.active_values_from_days_seen_map( - os_used_month, - -6, - 7 - ) AS os_used_week, - `moz-fx-data-shared-prod`.udf.active_values_from_days_seen_map( - os_used_month, - -27, - 28 - ) AS os_used_month, - * EXCEPT (days_seen_bits, os_used_month, submission_date_pacific) REPLACE( - TIMESTAMP(submission_date_pacific, "America/Los_Angeles") AS timestamp - ) - FROM - `moz-fx-data-shared-prod`.firefox_accounts_derived.fxa_amplitude_export_v1 - WHERE - `moz-fx-data-shared-prod`.udf.pos_of_trailing_set_bit(days_seen_bits) = 0 -), -active_events AS ( - SELECT - submission_timestamp, - user_id, - insert_id, - 'fxa_activity - active' AS event_type, - timestamp, - TO_JSON_STRING( - STRUCT(services AS service, oauth_client_ids, rollup_events) - ) AS event_properties, - region, - country, - `LANGUAGE`, - app_version AS version, - TO_JSON_STRING(os_used_day) AS os, - '' AS user_properties - FROM - active_users -), -user_properties AS ( - SELECT - submission_timestamp, - user_id, - '' AS insert_id, - '$identify' AS event_type, - timestamp, - '' AS event_properties, - -- Some Amplitude properties are top level - region, - country, - `LANGUAGE`, - app_version AS version, - TO_JSON_STRING(os_used_day) AS os, - -- We don't want to include user_properties if they are null, so we need - -- to list them out explicitly and filter with WHERE - CONCAT( - "{", - ARRAY_TO_STRING( - ARRAY( - SELECT - CONCAT(TO_JSON_STRING(key), ":", value) - FROM - ( - SELECT AS STRUCT - "os_used_day" AS key, - TO_JSON_STRING(os_used_day) AS value, - UNION ALL - SELECT AS STRUCT - "os_used_week" AS key, - TO_JSON_STRING(os_used_week) AS value, - UNION ALL - SELECT AS STRUCT - "os_used_month" AS key, - TO_JSON_STRING(os_used_month) AS value, - UNION ALL - SELECT AS STRUCT - "sync_device_count" AS key, - TO_JSON_STRING(sync_device_count) AS value, - UNION ALL - SELECT AS STRUCT - "sync_active_devices_day" AS key, - TO_JSON_STRING(sync_active_devices_day) AS value, - UNION ALL - SELECT AS STRUCT - "sync_active_devices_week" AS key, - TO_JSON_STRING(sync_active_devices_week) AS value, - UNION ALL - SELECT AS STRUCT - "sync_active_devices_month" AS key, - TO_JSON_STRING(sync_active_devices_month) AS value, - UNION ALL - SELECT AS STRUCT - "ua_version" AS key, - TO_JSON_STRING(ua_version) AS value, - UNION ALL - SELECT AS STRUCT - "ua_browser" AS key, - TO_JSON_STRING(ua_browser) AS value, - UNION ALL - SELECT AS STRUCT - "$postInsert", - TO_JSON_STRING(STRUCT(fxa_services_used)) AS value - ) - WHERE - value != "null" - AND value != "[]" - ), - "," - ), - "}" - ) AS user_properties - FROM - active_users -), -all_events AS ( - SELECT - * - FROM - active_events - UNION ALL - SELECT - * - FROM - user_properties -) -SELECT - * -FROM - all_events diff --git a/sql/moz-fx-data-shared-prod/firefox_accounts/sync_send_tab_export/view.sql b/sql/moz-fx-data-shared-prod/firefox_accounts/sync_send_tab_export/view.sql deleted file mode 100644 index 1e84ab29f64..00000000000 --- a/sql/moz-fx-data-shared-prod/firefox_accounts/sync_send_tab_export/view.sql +++ /dev/null @@ -1,106 +0,0 @@ --- Sampled view on send tab metrics intended for sending to Amplitude; --- see https://bugzilla.mozilla.org/show_bug.cgi?id=1628740 -CREATE OR REPLACE VIEW - `moz-fx-data-shared-prod.firefox_accounts.sync_send_tab_export` -AS -WITH events AS ( - SELECT - *, - `moz-fx-data-shared-prod`.udf.deanonymize_event(event).* - FROM - `moz-fx-data-shared-prod.telemetry.sync` - CROSS JOIN - UNNEST(payload.events) AS event -), -cleaned AS ( - SELECT - *, - payload.device_id, - `moz-fx-data-shared-prod`.udf.get_key(event_map_values, 'serverTime') AS server_time, - `moz-fx-data-shared-prod`.udf.normalize_os(payload.os.name) AS os_name, - CASE - event_object - WHEN - 'processcommand' - THEN - 'sync - tab_received' - WHEN - 'sendcommand' - THEN - 'sync - tab_sent' - END - AS event_type, - `moz-fx-data-shared-prod`.udf.get_key(event_map_values, 'flowID') AS flow_id, - FROM - events - WHERE - event_method = 'displayURI' -) -SELECT - cleaned.submission_timestamp, - ids.user_id, - device_id, - ARRAY_TO_STRING( - [device_id, event_category, event_method, event_object, server_time, flow_id], - '-' - ) AS insert_id, - -- Amplitude expects a `time` field in milliseconds since UNIX epoch. - COALESCE( - -- server_time is in seconds, but with one digit after the decimal place, so we - -- have to cast to float, multiply to get milliseconds, then cast to int. - SAFE_CAST(SAFE_CAST(server_time AS FLOAT64) * 1000 AS INT64), - -- server_time is sometimes null, so we fall back to submission_timestamp - UNIX_MILLIS(cleaned.submission_timestamp) - ) AS time, - event_type, - metadata.geo.country, - metadata.geo.city, - os_name, - payload.os.version AS os_version, - payload.os.locale AS `language`, - FORMAT( - '{%t}', - ARRAY_TO_STRING( - ARRAY( - SELECT - FORMAT('"%t":"%t"', key, value) - FROM - UNNEST( - [ - STRUCT('fxa_uid' AS key, ids.user_id AS value), - STRUCT('ua_browser', metadata.user_agent.browser), - STRUCT('ua_version', metadata.user_agent.version) - ] - ) - WHERE - value IS NOT NULL - ), - ',' - ) - ) AS user_properties, - FORMAT( - '{%t}', - ARRAY_TO_STRING( - ARRAY( - SELECT - FORMAT('"%t":"%t"', key, value) - FROM - UNNEST([STRUCT('flow_id' AS key, flow_id AS value)]) - WHERE - value IS NOT NULL - ), - ',' - ) - ) AS event_properties, -FROM - cleaned --- We need this join because sync pings contain a truncated ID that is just the --- first 32 characters of the 64-character hash sent to Amplitude by other producers; --- we join based on the prefix to recover the full 64-character hash. -LEFT JOIN - `moz-fx-data-shared-prod.firefox_accounts_derived.fxa_amplitude_user_ids_v1` AS ids -ON - cleaned.payload.uid = SUBSTR(ids.user_id, 1, 32) -WHERE - -- To save on Amplitude budget, we take a 10% sample based on user ID. - MOD(ABS(FARM_FINGERPRINT(payload.uid)), 100) < 10 diff --git a/sql/moz-fx-data-shared-prod/messaging_system/onboarding_events_amplitude/view.sql b/sql/moz-fx-data-shared-prod/messaging_system/onboarding_events_amplitude/view.sql deleted file mode 100644 index 89f6228eb6b..00000000000 --- a/sql/moz-fx-data-shared-prod/messaging_system/onboarding_events_amplitude/view.sql +++ /dev/null @@ -1,36 +0,0 @@ -CREATE OR REPLACE VIEW - `moz-fx-data-shared-prod.messaging_system.onboarding_events_amplitude` -AS -SELECT - submission_timestamp, - client_id AS device_id, - document_id AS insert_id, - event AS event_type, - submission_timestamp AS timestamp, - version AS app_version, - REGEXP_EXTRACT(metadata.user_agent.os, '^\\w+') AS platform, - metadata.user_agent.os AS os_name, - normalized_os_version AS os_version, - metadata.geo.country AS country, - metadata.geo.subdivision1 AS region, - metadata.geo.city AS city, - ( - `moz-fx-data-shared-prod.udf.kv_array_append_to_json_string`( - event_context, - [STRUCT("message_id" AS key, message_id AS value)] - ) - ) AS event_properties, - TO_JSON_STRING( - STRUCT( - locale, - release_channel, - ARRAY(SELECT CONCAT(key, " - ", value.branch) FROM UNNEST(experiments)) AS experiments, - attribution.source AS attribution_source, - attribution.ua AS attribution_ua - ) - ) AS user_properties -FROM - `moz-fx-data-shared-prod.messaging_system_stable.onboarding_v1` -WHERE - -- Fetch events on about:welcome only to minimize the event volume - event_context LIKE "%about:welcome%" diff --git a/sql/moz-fx-data-shared-prod/messaging_system/onboarding_retention_events_amplitude/view.sql b/sql/moz-fx-data-shared-prod/messaging_system/onboarding_retention_events_amplitude/view.sql deleted file mode 100644 index 83151d779ab..00000000000 --- a/sql/moz-fx-data-shared-prod/messaging_system/onboarding_retention_events_amplitude/view.sql +++ /dev/null @@ -1,30 +0,0 @@ -CREATE OR REPLACE VIEW - `moz-fx-data-shared-prod.messaging_system.onboarding_retention_events_amplitude` -AS -SELECT - TIMESTAMP(submission_date) AS submission_timestamp, - client_id AS device_id, - CONCAT(client_id, submission_date) AS insert_id, - "RETENTION" AS event_type, - TIMESTAMP(submission_date) AS timestamp, - app_version, - REGEXP_EXTRACT(os, '^\\w+') AS platform, - os AS os_name, - os_version, - cd.country AS country, - geo_subdivision1 AS region, - city, - -- No `event_properties` for this event - TO_JSON_STRING( - STRUCT( - cd.locale AS locale, - channel AS release_channel, - ARRAY(SELECT CONCAT(key, " - ", value) FROM UNNEST(experiments)) AS experiments - ) - ) AS user_properties -FROM - `moz-fx-data-shared-prod.messaging_system.onboarding_users_last_seen` -JOIN - `moz-fx-data-shared-prod.telemetry.clients_daily` cd -USING - (client_id, submission_date) diff --git a/sql/moz-fx-data-shared-prod/telemetry_derived/devtools_events_amplitude_v1/view.sql b/sql/moz-fx-data-shared-prod/telemetry_derived/devtools_events_amplitude_v1/view.sql deleted file mode 100755 index c05b1536381..00000000000 --- a/sql/moz-fx-data-shared-prod/telemetry_derived/devtools_events_amplitude_v1/view.sql +++ /dev/null @@ -1,214 +0,0 @@ -CREATE OR REPLACE VIEW - `moz-fx-data-shared-prod.telemetry_derived.devtools_events_amplitude_v1` - OPTIONS( - description="A view for extracting Devtools events to Amplitude. Compatible with event taxonomy from legacy Spark jobs." - ) AS -WITH event_events AS ( - SELECT - DATE(submission_timestamp) AS submission_date, - 'event' AS doc_type, - document_id, - client_id, - normalized_channel, - normalized_country_code AS country, - environment.settings.locale AS locale, - normalized_app_name AS app_name, - metadata.uri.app_version AS app_version, - normalized_os AS os, - normalized_os_version AS os_version, - environment.experiments AS experiments, - sample_id, - payload.session_id AS session_id, - SAFE.TIMESTAMP_MILLIS(payload.process_start_timestamp) AS session_start_time, - payload.subsession_id AS subsession_id, - submission_timestamp AS `timestamp`, - `moz-fx-data-shared-prod.udf.deanonymize_event`(e).*, - event_process, - environment.build.architecture AS env_build_arch, - application.build_id AS application_build_id, - environment.settings.is_default_browser, - environment.system.is_wow64, - environment.system.memory_mb, - environment.profile.creation_date AS profile_creation_date, - environment.settings.attribution.source AS attribution_source, - metadata.geo.city - FROM - `moz-fx-data-shared-prod.telemetry.event` - CROSS JOIN - UNNEST( - [ - STRUCT( - "content" AS event_process, - payload.events.content AS events - ), - ("dynamic", payload.events.dynamic), - ("extension", payload.events.extension), - ("gpu", payload.events.gpu), - ("parent", payload.events.parent) - ] - ) - CROSS JOIN - UNNEST(events) AS e -), main_events AS ( - SELECT - DATE(submission_timestamp) AS submission_date, - 'main' AS doc_type, - document_id, - client_id, - normalized_channel, - normalized_country_code AS country, - environment.settings.locale AS locale, - normalized_app_name AS app_name, - metadata.uri.app_version AS app_version, - normalized_os AS os, - normalized_os_version AS os_version, - environment.experiments AS experiments, - sample_id, - payload.info.session_id AS session_id, - SAFE.PARSE_TIMESTAMP( - "%FT%H:%M:%S.0%Ez", - payload.info.session_start_date - ) AS session_start_time, - payload.info.subsession_id AS subsession_id, - submission_timestamp AS `timestamp`, - `moz-fx-data-shared-prod.udf.deanonymize_event`(e).*, - event_process, - environment.build.architecture AS env_build_arch, - application.build_id AS application_build_id, - environment.settings.is_default_browser, - environment.system.is_wow64, - environment.system.memory_mb, - environment.profile.creation_date AS profile_creation_date, - environment.settings.attribution.source AS attribution_source, - metadata.geo.city - FROM - `moz-fx-data-shared-prod.telemetry.main` - CROSS JOIN - -- While there are more "events" fields under other process in the main ping schema, - -- events were moved out to the event ping before those other processes were added. This is - -- an exhaustive list of processes in which we'd expect to see events in main pings - UNNEST( - [ - STRUCT( - "content" AS event_process, - payload.processes.content.events AS events - ), - ("dynamic", payload.processes.dynamic.events), - ("gpu", payload.processes.gpu.events), - ("parent", payload.processes.parent.events) - ] - ) - CROSS JOIN - UNNEST(events) AS e -), events AS ( - SELECT - * - FROM - main_events - UNION ALL - SELECT - * - FROM - event_events -), base_events AS ( - SELECT - *, - timestamp AS submission_timestamp, - event_string_value AS event_value, - UNIX_MILLIS(session_start_time) AS created - FROM - events -), all_events AS ( -SELECT - submission_timestamp, - client_id AS user_id, - (created + COALESCE(SAFE_CAST(`moz-fx-data-shared-prod.udf.get_key`(event_map_values, 'session_id') AS INT64), 0)) AS session_id, - CASE - WHEN event_object = 'tools' THEN CONCAT('dt - ', event_method) - WHEN event_object = 'debugger' THEN CONCAT('dt_jsdebugger - ', event_method) - WHEN event_object = 'aboutdebugging' THEN CONCAT('dt_adbg - ', event_method) - WHEN event_category = 'devtools.main' THEN CONCAT('dt_', event_object, ' - ', event_method) - END AS event_name, - event_timestamp AS timestamp, - (event_timestamp + created) AS time, - app_version, - os AS os_name, - os_version, - country, - city, - (SELECT - ARRAY_AGG(CONCAT('"', - CAST(key AS STRING), '":"', - CAST(value AS STRING), '"')) - FROM - UNNEST(event_map_values)) AS event_props, - event_map_values, - event_object, - event_value, - event_method, - event_category, - created, - NULL AS settings, - normalized_channel, - env_build_arch, - sample_id, - application_build_id, - app_name, - locale, - is_default_browser, - is_wow64, - memory_mb, - profile_creation_date, - attribution_source, - (SELECT ARRAY_AGG(CONCAT(key,'_',value.branch)) from UNNEST(experiments)) as experiments -FROM - base_events -WHERE - (doc_type IN ('main', 'event') AND app_name = 'Firefox' AND normalized_channel IN ('nightly', 'aurora')) - AND event_category = 'devtools.main' - AND event_method NOT IN ('edit_rule', 'tool_timer') -), all_events_with_insert_ids AS ( -SELECT - * EXCEPT (event_category, created), - CONCAT(user_id, "-", CAST(created AS STRING), "-", SPLIT(event_name, " - ")[OFFSET(1)], "-", CAST(timestamp AS STRING), "-", event_category, "-", event_method, "-", event_object) AS insert_id, - event_name AS event_type -FROM - all_events -WHERE - event_name IS NOT NULL -), extra_props AS ( -SELECT - * EXCEPT (event_map_values, event_object, event_value, event_method, event_name), - ARRAY_CONCAT((SELECT ARRAY_AGG(CONCAT('"', CAST(key AS STRING), '":"', CAST(value AS STRING), '"')) FROM ( - SELECT 'host' AS key, `moz-fx-data-shared-prod.udf.get_key`(event_map_values, 'host') AS value - UNION ALL SELECT 'width' AS key, `moz-fx-data-shared-prod.udf.get_key`(event_map_values, 'width') AS value - UNION ALL SELECT 'channel' AS key, normalized_channel AS value - UNION ALL SELECT 'app_build_id' AS key, application_build_id AS value - UNION ALL SELECT 'app_name' AS key, app_name AS value - UNION ALL SELECT 'locale' AS key, locale AS value - UNION ALL SELECT 'country' AS key, country AS value - UNION ALL SELECT 'env_build_arch' AS key, env_build_arch AS value - UNION ALL SELECT 'source' AS key, attribution_source AS value - UNION ALL SELECT 'profile_creation_date' AS key, CAST(SAFE.DATE_FROM_UNIX_DATE(CAST(profile_creation_date AS INT64)) AS STRING) AS value -)), -(SELECT ARRAY_AGG(CONCAT('"', CAST(key AS STRING), '":', CAST(value AS STRING))) FROM ( - SELECT 'experiments' AS key, CONCAT('["', ARRAY_TO_STRING(experiments, '","'),'"]') AS value - UNION ALL SELECT 'sample_id' AS key, CAST(sample_id AS STRING) AS value - UNION ALL SELECT 'is_default_browser' AS key, CAST(is_default_browser AS STRING) AS value - UNION ALL SELECT 'is_wow64' AS key, CAST(is_wow64 AS STRING) AS value - UNION ALL SELECT 'memory_mb' AS key, CAST(memory_mb AS STRING) AS value -)) - ) AS user_props -FROM - all_events_with_insert_ids -) - -SELECT - * EXCEPT (event_props, user_props, settings, normalized_channel, env_build_arch, sample_id, - application_build_id, app_name, locale, is_default_browser, is_wow64, memory_mb, profile_creation_date, - attribution_source, experiments), - CONCAT('{', ARRAY_TO_STRING(( - SELECT ARRAY_AGG(DISTINCT e) FROM UNNEST(ARRAY_CONCAT(event_props)) AS e - ), ","), '}') AS event_properties, - CONCAT('{', ARRAY_TO_STRING(user_props, ","), '}') AS user_properties -FROM extra_props