├── README.md ├── google-analytics-bigquery-legacy-export.sql └── google-analytics-bigquery-standard-export.sql /README.md: -------------------------------------------------------------------------------- 1 | # Google Analytics BigQuery data export 2 | This repository contains SQL code to export data from Google Analytics in BigQuery, using standard or legacy SQL. 3 | 4 | # Data Extract 5 | ### Google Analytics Data BigQuery Export 6 | Both SQL queries below transform Google Analytics BigQuery nested data into flat hit level data with a timestamp making data easy to analyze using tools like Tableau, SAS, R, etc. 7 | 8 | - google-analytics-bigquery-legacy-export.sql 9 | - google-analytics-bigquery-standard-export.sql 10 | 11 | ##### Instructions: 12 | 1. Open the SQL and configure the table(s) to export 13 | 3. Output the results to another table and export to Google Storage 14 | 4. Download the CSVs, done! -------------------------------------------------------------------------------- /google-analytics-bigquery-legacy-export.sql: -------------------------------------------------------------------------------- 1 | -- Export Google Analytics BigQuery data using legacy SQL 2 | -- 3 | -- Keep the #legacySQL comment on your query to instruct BigQuery to use legacy SQL 4 | -- Authors: Joao Correia 5 | -- License: Apache License Version 2.0 6 | 7 | #legacySQL 8 | SELECT 9 | STRFTIME_UTC_USEC(SEC_TO_TIMESTAMP(visitStartTime + hits.time/1000),"%Y-%m-%d %H:%M:%S") as hit.timestamp, 10 | -- ROUND(visitStartTime + hits.time/1000) as hits.timestamp, /* Use for UNIX timestamp instead of timestamp */ 11 | visitNumber, 12 | visitId, 13 | fullVisitorId, 14 | STRFTIME_UTC_USEC(SEC_TO_TIMESTAMP(visitStartTime),"%Y-%m-%d %H:%M:%S") as hit.visitStartTime, 15 | LEFT(date,4)+"-"+SUBSTR(date,5,2)+"-"+RIGHT(date,2) as date, 16 | trafficSource.referralPath, 17 | trafficSource.campaign, 18 | trafficSource.source, 19 | trafficSource.medium, 20 | trafficSource.keyword, 21 | trafficSource.adContent, 22 | device.browser, 23 | device.browserVersion, 24 | device.operatingSystem, 25 | device.operatingSystemVersion, 26 | device.isMobile, 27 | device.mobileDeviceBranding, /* Only Availabe is later schemas */ 28 | device.flashVersion, 29 | device.javaEnabled, 30 | device.language, 31 | device.screenColors, 32 | device.screenResolution, 33 | device.deviceCategory, 34 | geoNetwork.continent, 35 | geoNetwork.subContinent, 36 | geoNetwork.country, 37 | geoNetwork.region, 38 | geoNetwork.metro 39 | hits.type, 40 | hits.social.socialInteractionNetwork, 41 | hits.social.socialInteractionAction, 42 | hits.hitNumber, 43 | (hits.time/1000) as hits.time, /* Converted to seconds */ 44 | hits.hour, 45 | hits.minute, 46 | hits.isSecure, 47 | hits.isInteraction, 48 | hits.referer, 49 | hits.page.pagePath, 50 | hits.page.hostname, 51 | hits.page.pageTitle, 52 | hits.page.searchKeyword, 53 | hits.page.searchCategory, 54 | 55 | -- Ecommerce 56 | hits.transaction.transactionId, 57 | hits.transaction.transactionRevenue, 58 | hits.transaction.transactionTax, 59 | hits.transaction.transactionShipping, 60 | hits.transaction.affiliation, 61 | hits.transaction.currencyCode, 62 | hits.transaction.localTransactionRevenue, 63 | hits.transaction.localTransactionTax, 64 | hits.transaction.localTransactionShipping, 65 | hits.transaction.transactionCoupon, 66 | hits.item.transactionId, 67 | hits.item.productName, 68 | hits.item.productCategory, 69 | hits.item.productSku, 70 | hits.item.itemQuantity, 71 | hits.item.itemRevenue, 72 | hits.item.currencyCode, 73 | hits.item.localItemRevenue, 74 | 75 | -- Enhanced Ecommerce 76 | hits.eCommerceAction.action_type, 77 | hits.eCommerceAction.step, 78 | hits.eCommerceAction.option, 79 | 80 | hits.product.productSKU, 81 | hits.product.v2ProductName, 82 | hits.product.v2ProductCategory, 83 | hits.product.productVariant, 84 | hits.product.productBrand, 85 | hits.product.productRevenue, 86 | hits.product.localProductRevenue, 87 | hits.product.productPrice, 88 | hits.product.localProductPrice, 89 | hits.product.productQuantity, 90 | hits.product.productRefundAmount, 91 | hits.product.localProductRefundAmount, 92 | hits.product.isImpression, 93 | 94 | hits.refund.refundAmount, 95 | hits.refund.localRefundAmount, 96 | 97 | -- Promotion 98 | hits.promotion.promoId, 99 | hits.promotion.promoName, 100 | hits.promotion.promoCreative, 101 | hits.promotion.promoPosition, 102 | 103 | -- Mobile App 104 | hits.contentInfo.contentDescription, 105 | hits.appInfo.name, 106 | hits.appInfo.version, 107 | hits.appInfo.id, 108 | hits.appInfo.installerId, 109 | hits.appInfo.appInstallerId, 110 | hits.appInfo.appName, 111 | hits.appInfo.appVersion, 112 | hits.appInfo.appId, 113 | hits.appInfo.screenName, 114 | hits.appInfo.landingScreenName, 115 | hits.appInfo.exitScreenName, 116 | hits.appInfo.screenDepth, 117 | hits.exceptionInfo.description, 118 | hits.exceptionInfo.isFatal, 119 | 120 | -- Events 121 | hits.eventInfo.eventCategory, 122 | hits.eventInfo.eventAction, 123 | hits.eventInfo.eventLabel, 124 | hits.eventInfo.eventValue, 125 | 126 | 127 | -- Custom Dimensions (Add your custom dimensions by adding a line for each dimension) 128 | MAX(IF (hits.customDimensions.index = 1, hits.customDimensions.value, NULL)) WITHIN RECORD AS dimension1, 129 | 130 | -- Custom Metrics (Add your custom metrics by adding a line for each metric) 131 | MAX(IF (hits.customMetrics.index = 1, hits.customMetrics.value, NULL)) WITHIN RECORD AS metric1, 132 | 133 | -- SQL Custom Variables (Use only the ) 134 | MAX(IF (hits.customVariables.index = 1, hits.customVariables.customVarName, NULL)) WITHIN RECORD AS cv1Key, 135 | MAX(IF (hits.customVariables.index = 1, hits.customVariables.customVarValue, NULL)) WITHIN RECORD AS cv1Value, 136 | 137 | FROM [dataset_id.ga_sessions_YYYYMMDD] -------------------------------------------------------------------------------- /google-analytics-bigquery-standard-export.sql: -------------------------------------------------------------------------------- 1 | -- Export Google Analytics BigQuery data using standard SQL 2 | -- 3 | -- Keep the #standardSQL comment on your query to instruct BigQuery to use standard SQL (BigQuery dialect) 4 | -- Authors: Joao Correia 5 | -- License: Apache License Version 2.0 6 | 7 | #standardSQL 8 | SELECT 9 | -- Hits are recorded in UTC. Customize your timezone to convert to your timezone. 10 | FORMAT_TIMESTAMP("%Y-%m-%d %H:%M:%S", TIMESTAMP_SECONDS(SAFE_CAST(visitStartTime+hits.time/1000 AS INT64)), "America/Los_Angeles") AS hit_timestamp, 11 | visitNumber, 12 | visitId, 13 | fullVisitorId, 14 | FORMAT_TIMESTAMP("%Y-%m-%d %H:%M:%S", TIMESTAMP_SECONDS(SAFE_CAST(visitStartTime AS INT64)), "America/Los_Angeles") AS hit_visitStartTime, 15 | CONCAT(SUBSTR(date,0,4),"-",SUBSTR(date,5,2),"-",SUBSTR(date,7,2)) AS date, 16 | trafficSource.referralPath, 17 | trafficSource.campaign, 18 | trafficSource.source, 19 | trafficSource.medium, 20 | trafficSource.keyword, 21 | trafficSource.adContent, 22 | device.browser, 23 | device.browserVersion, 24 | device.operatingSystem, 25 | device.operatingSystemVersion, 26 | device.isMobile, 27 | device.mobileDeviceBranding, /* Only Availabe is later schemas */ 28 | device.flashVersion, 29 | device.javaEnabled, 30 | device.language, 31 | device.screenColors, 32 | device.screenResolution, 33 | device.deviceCategory, 34 | geoNetwork.continent, 35 | geoNetwork.subContinent, 36 | geoNetwork.country, 37 | geoNetwork.region, 38 | geoNetwork.metro, 39 | hits.type, 40 | hits.social.socialInteractionNetwork, 41 | hits.social.socialInteractionAction, 42 | hits.hitNumber, 43 | hits.time/1000 AS hits_time, /* Converted to seconds */ 44 | hits.hour, 45 | hits.minute, 46 | hits.isSecure, 47 | hits.isInteraction, 48 | hits.referer, 49 | hits.page.pagePath, 50 | hits.page.hostname, 51 | hits.page.pageTitle, 52 | hits.page.searchKeyword, 53 | hits.page.searchCategory, 54 | 55 | -- Ecommerce 56 | hits.transaction.transactionId AS hit_transactionId, 57 | hits.transaction.transactionRevenue, 58 | hits.transaction.transactionTax, 59 | hits.transaction.transactionShipping, 60 | hits.transaction.affiliation, 61 | hits.transaction.currencyCode AS hit_transaction_currencyCode, 62 | hits.transaction.localTransactionRevenue, 63 | hits.transaction.localTransactionTax, 64 | hits.transaction.localTransactionShipping, 65 | hits.transaction.transactionCoupon, 66 | hits.item.transactionId, 67 | hits.item.productName, 68 | hits.item.productCategory, 69 | hits.item.productSku, 70 | hits.item.itemQuantity, 71 | hits.item.itemRevenue, 72 | hits.item.currencyCode, 73 | hits.item.localItemRevenue, 74 | 75 | 76 | -- Enhanced Ecommerce 77 | hits.eCommerceAction.action_type, 78 | hits.eCommerceAction.step, 79 | hits.eCommerceAction.option, 80 | 81 | (SELECT productSKU FROM UNNEST(hits.product)) AS hits_product_v2ProductSKU, 82 | (SELECT v2ProductName FROM UNNEST(hits.product)) AS hits_product_v2ProductName, 83 | (SELECT v2ProductCategory FROM UNNEST(hits.product)) AS hits_product_v2ProductCategory, 84 | (SELECT productVariant FROM UNNEST(hits.product)) AS hits_product_productVariant, 85 | (SELECT productBrand FROM UNNEST(hits.product)) AS hits_product_productBrand, 86 | (SELECT productRevenue FROM UNNEST(hits.product)) AS hits_product_productRevenue, 87 | (SELECT localProductRevenue FROM UNNEST(hits.product)) AS hits_product_localProductRevenue, 88 | (SELECT productPrice FROM UNNEST(hits.product)) AS hits_product_productPrice, 89 | (SELECT localProductPrice FROM UNNEST(hits.product)) AS hits_product_localProductPrice, 90 | (SELECT productQuantity FROM UNNEST(hits.product)) AS hits_product_productQuantity, 91 | (SELECT productRefundAmount FROM UNNEST(hits.product)) AS hits_product_productRefundAmount, 92 | (SELECT isImpression FROM UNNEST(hits.product)) AS isImpression, 93 | 94 | hits.refund.refundAmount, 95 | hits.refund.localRefundAmount, 96 | 97 | -- Promotion 98 | (SELECT promoId FROM UNNEST(hits.promotion)) AS hits_promotion_promoId, 99 | (SELECT promoName FROM UNNEST(hits.promotion)) AS hits_promotion_promoName, 100 | (SELECT promoCreative FROM UNNEST(hits.promotion)) AS hits_promotion_promoCreative, 101 | (SELECT promoPosition FROM UNNEST(hits.promotion)) AS hits_promotion_promoPosition, 102 | 103 | -- Mobile App 104 | hits.contentInfo.contentDescription, 105 | hits.appInfo.name, 106 | hits.appInfo.version, 107 | hits.appInfo.id, 108 | hits.appInfo.installerId, 109 | hits.appInfo.appInstallerId, 110 | hits.appInfo.appName, 111 | hits.appInfo.appVersion, 112 | hits.appInfo.appId, 113 | hits.appInfo.screenName, 114 | hits.appInfo.landingScreenName, 115 | hits.appInfo.exitScreenName, 116 | hits.appInfo.screenDepth, 117 | hits.exceptionInfo.description, 118 | hits.exceptionInfo.isFatal, 119 | 120 | -- Events 121 | hits.eventInfo.eventCategory, 122 | hits.eventInfo.eventAction, 123 | hits.eventInfo.eventLabel, 124 | hits.eventInfo.eventValue, 125 | 126 | -- Custom Dimensions (Add your custom dimensions by adding a line for each dimension and chaging the index) 127 | (SELECT MAX(IF(index=1, value, NULL)) FROM UNNEST(hits.customDimensions)) AS dimension1, 128 | 129 | -- Custom Metrics (Add your custom metrics by adding a line for each metric) 130 | (SELECT MAX(IF(index=1, value, NULL)) FROM UNNEST(hits.customMetrics)) AS metric1 131 | 132 | FROM `dataset_id.ga_sessions_YYYYMMDD` , UNNEST(hits) as hits 133 | --------------------------------------------------------------------------------