├── .github ├── CODEOWNERS ├── pull_request_template.md └── ISSUE_TEMPLATE │ ├── feature_request.md │ └── bug_report.md ├── .gitignore ├── packages.yml ├── models └── router │ ├── stitch │ ├── adwords_ads.sql │ ├── adwords_accounts.sql │ ├── adwords_ad_groups.sql │ ├── adwords_campaigns.sql │ ├── adwords_click_performance.sql │ ├── adwords_url_performance.sql │ └── adwords_criteria_performance.sql │ ├── fivetran │ ├── adwords_click_performance.sql │ ├── adwords_url_performance.sql │ └── adwords_criteria_performance.sql │ ├── adapter │ ├── url │ │ └── adwords_ad_performance_adapter.sql │ └── criteria │ │ └── adwords_ad_performance_adapter.sql │ └── schema.yml ├── macros ├── stitch │ ├── stitch_adwords_ads.sql │ ├── stitch_adwords_click_performance.sql │ ├── stitch_adwords_accounts.sql │ ├── stitch_adwords_ad_groups.sql │ ├── stitch_adwords_campaigns.sql │ ├── stitch_adwords_criteria_performance.sql │ └── stitch_adwords_url_performance.sql ├── fivetran │ ├── fivetran_adwords_click_performance.sql │ ├── fivetran_adwords_criteria_performance.sql │ └── fivetran_adwords_url_performance.sql └── adapters │ ├── stitch_adwords_adapter_criteria.sql │ └── stitch_adwords_adapter_url.sql ├── dbt_project.yml ├── README.md └── LICENSE /.github/CODEOWNERS: -------------------------------------------------------------------------------- 1 | * @dbt-labs/dbt-package-owners 2 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | target/ 2 | dbt_modules/ 3 | logs/ 4 | -------------------------------------------------------------------------------- /packages.yml: -------------------------------------------------------------------------------- 1 | packages: 2 | - package: dbt-labs/dbt_utils 3 | version: [">=0.7.0", "<0.9.0"] -------------------------------------------------------------------------------- /models/router/stitch/adwords_ads.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'stitch' 4 | ) 5 | }} 6 | 7 | {{ stitch_adwords_ads() }} -------------------------------------------------------------------------------- /models/router/stitch/adwords_accounts.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'stitch' 4 | ) 5 | }} 6 | 7 | {{ stitch_adwords_accounts() }} -------------------------------------------------------------------------------- /models/router/stitch/adwords_ad_groups.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'stitch' 4 | ) 5 | }} 6 | 7 | {{ stitch_adwords_ad_groups() }} -------------------------------------------------------------------------------- /models/router/stitch/adwords_campaigns.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'stitch' 4 | ) 5 | }} 6 | 7 | {{ stitch_adwords_campaigns() }} -------------------------------------------------------------------------------- /models/router/stitch/adwords_click_performance.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'stitch' 4 | ) 5 | }} 6 | 7 | {{ stitch_adwords_click_performance() }} 8 | -------------------------------------------------------------------------------- /models/router/fivetran/adwords_click_performance.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'fivetran' 4 | ) 5 | }} 6 | 7 | {{ fivetran_adwords_click_performance() }} 8 | -------------------------------------------------------------------------------- /models/router/stitch/adwords_url_performance.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'stitch' and var('adapter_value') == 'url' 4 | ) 5 | }} 6 | 7 | {{ stitch_adwords_url_performance() }} 8 | -------------------------------------------------------------------------------- /models/router/fivetran/adwords_url_performance.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'fivetran' and var('adapter_value') == 'url' 4 | ) 5 | }} 6 | 7 | {{ fivetran_adwords_url_performance() }} 8 | -------------------------------------------------------------------------------- /models/router/stitch/adwords_criteria_performance.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'stitch' and var('adapter_value') == 'criteria' 4 | ) 5 | }} 6 | 7 | {{ stitch_adwords_criteria_performance() }} -------------------------------------------------------------------------------- /models/router/fivetran/adwords_criteria_performance.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('etl') == 'fivetran' and var('adapter_value') == 'criteria' 4 | ) 5 | }} 6 | 7 | {{ fivetran_adwords_criteria_performance() }} -------------------------------------------------------------------------------- /.github/pull_request_template.md: -------------------------------------------------------------------------------- 1 | ## Description & motivation 2 | 5 | 6 | ## Checklist 7 | - [ ] I have verified that these changes work locally 8 | - [ ] I have updated the README.md (if applicable) 9 | - [ ] I have added tests & descriptions to my models (and macros if applicable) -------------------------------------------------------------------------------- /models/router/adapter/url/adwords_ad_performance_adapter.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('adapter_value') == 'url' 4 | ) 5 | }} 6 | 7 | with url_base as ( 8 | 9 | select * from {{ ref('adwords_url_performance') }} 10 | 11 | ), 12 | 13 | final as ( 14 | 15 | select 16 | date_day as campaign_date, 17 | ad_group_id, 18 | ad_group_name, 19 | campaign_id, 20 | url_host, 21 | url_path, 22 | utm_source, 23 | utm_medium, 24 | utm_campaign, 25 | utm_term, 26 | campaign_name, 27 | clicks, 28 | impressions, 29 | spend, 30 | 'adwords' as platform 31 | 32 | from url_base 33 | 34 | ) 35 | 36 | select * from final 37 | -------------------------------------------------------------------------------- /macros/stitch/stitch_adwords_ads.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_ads() %} 2 | 3 | {{ adapter.dispatch('stitch_adwords_ads', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__stitch_adwords_ads() %} 9 | 10 | with ads_source as ( 11 | 12 | select * from {{ var('ads_table') }} 13 | 14 | ), 15 | 16 | ads_renamed as ( 17 | 18 | select 19 | 20 | adgroupid as ad_id, 21 | baseadgroupid as base_ad_group_id, 22 | basecampaignid as base_campaign_id, 23 | policysummary as policy_summary, 24 | status, 25 | "_SDC_CUSTOMER_ID" as account_id 26 | 27 | from ads_source 28 | 29 | ) 30 | 31 | select * from ads_renamed 32 | 33 | {% endmacro %} -------------------------------------------------------------------------------- /macros/fivetran/fivetran_adwords_click_performance.sql: -------------------------------------------------------------------------------- 1 | {% macro fivetran_adwords_click_performance() %} 2 | 3 | {{ adapter.dispatch('fivetran_adwords_click_performance', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__fivetran_adwords_click_performance() %} 9 | 10 | with gclid_base as ( 11 | 12 | select 13 | 14 | gcl_id as gclid, 15 | date::date as date_day, 16 | criteria_id, 17 | ad_group_id, 18 | row_number() over (partition by gclid order by date_day) as row_num 19 | 20 | from {{ var('click_performance_report') }} 21 | 22 | ) 23 | 24 | select * from gclid_base 25 | where row_num = 1 26 | and gclid is not null 27 | 28 | {% endmacro %} -------------------------------------------------------------------------------- /macros/stitch/stitch_adwords_click_performance.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_click_performance() %} 2 | 3 | {{ adapter.dispatch('stitch_adwords_click_performance', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__stitch_adwords_click_performance() %} 9 | 10 | with gclid_base as ( 11 | 12 | select 13 | 14 | googleclickid as gclid, 15 | day::date as date_day, 16 | keywordid as criteria_id, 17 | adgroupid as ad_group_id, 18 | row_number() over (partition by gclid order by date_day) as row_num 19 | 20 | from {{ var('click_performance_report') }} 21 | 22 | ) 23 | 24 | select * from gclid_base 25 | where row_num = 1 26 | and gclid is not null 27 | 28 | {% endmacro %} -------------------------------------------------------------------------------- /models/router/adapter/criteria/adwords_ad_performance_adapter.sql: -------------------------------------------------------------------------------- 1 | {{ 2 | config( 3 | enabled = var('adapter_value') == 'criteria' 4 | ) 5 | }} 6 | 7 | with criteria_base as ( 8 | 9 | select * from {{ ref('adwords_criteria_performance') }} 10 | 11 | ), 12 | 13 | final as ( 14 | 15 | select 16 | date_day as campaign_date, 17 | criteria_id, 18 | ad_group_name, 19 | ad_group_id, 20 | ad_group_state, 21 | campaign_name, 22 | campaign_id, 23 | campaign_state, 24 | customer_id, 25 | clicks, 26 | impressions, 27 | spend, 28 | 'adwords' as platform 29 | 30 | from criteria_base 31 | ) 32 | 33 | select * from final -------------------------------------------------------------------------------- /macros/adapters/stitch_adwords_adapter_criteria.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_adapter_criteria() %} 2 | 3 | with criteria_performance as ( 4 | 5 | select * from {{ ref('adwords_criteria_performance') }} 6 | 7 | ), 8 | 9 | joined as ( 10 | 11 | select 12 | 13 | date_day as campaign_date, 14 | ad_group_id, 15 | criteria_id, 16 | ad_group_name, 17 | campaign_id, 18 | campaign_name, 19 | clicks, 20 | spend, 21 | impressions, 22 | 'adwords' as platform 23 | 24 | from criteria_performance 25 | 26 | ) 27 | 28 | select * from joined 29 | 30 | {% endmacro %} -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/feature_request.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Feature request 3 | about: Suggest an idea for this package 4 | title: '' 5 | labels: enhancement, triage 6 | assignees: '' 7 | 8 | --- 9 | 10 | ### Describe the feature 11 | A clear and concise description of what you want to happen. 12 | 13 | ### Describe alternatives you've considered 14 | A clear and concise description of any alternative solutions or features you've considered. 15 | 16 | ### Additional context 17 | Is this feature database-specific? Which database(s) is/are relevant? Please include any other relevant context here. 18 | 19 | ### Who will this benefit? 20 | What kind of use case will this feature be useful for? Please be specific and provide examples, this will help us prioritize properly. -------------------------------------------------------------------------------- /macros/stitch/stitch_adwords_accounts.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_accounts() %} 2 | 3 | {{ adapter.dispatch('stitch_adwords_accounts', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__stitch_adwords_accounts() %} 9 | 10 | with accounts_source as ( 11 | 12 | select * from {{ var('accounts_table') }} 13 | 14 | ), 15 | 16 | accounts_renamed as ( 17 | 18 | select 19 | 20 | customerid as account_id, 21 | name as account_name, 22 | canmanageclients as can_manage_clients, 23 | currencycode as currency_code, 24 | datetimezone as time_zone, 25 | testaccount as test_account 26 | 27 | from accounts_source 28 | 29 | ) 30 | 31 | select * from accounts_renamed 32 | 33 | {% endmacro %} -------------------------------------------------------------------------------- /macros/adapters/stitch_adwords_adapter_url.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_adapter_url() %} 2 | 3 | with url_performance as ( 4 | 5 | select * from {{ ref('adwords_url_performance') }} 6 | 7 | ), 8 | 9 | joined as ( 10 | 11 | select 12 | 13 | date_day as campaign_date, 14 | url_host, 15 | url_path, 16 | utm_source, 17 | utm_medium, 18 | utm_campaign, 19 | utm_content, 20 | utm_term, 21 | ad_group_id, 22 | ad_group_name, 23 | campaign_id, 24 | campaign_name, 25 | clicks, 26 | spend, 27 | impressions, 28 | 'adwords' as platform 29 | 30 | from url_performance 31 | 32 | ) 33 | 34 | select * from joined 35 | 36 | {% endmacro %} -------------------------------------------------------------------------------- /dbt_project.yml: -------------------------------------------------------------------------------- 1 | name: 'adwords' 2 | version: '0.3.0' 3 | config-version: 2 4 | 5 | require-dbt-version: [">=1.0.0", "<2.0.0"] 6 | 7 | model-paths: ["models"] 8 | analysis-paths: ["analysis"] 9 | target-path: "target" 10 | clean-targets: ["target"] 11 | test-paths: ["test"] 12 | seed-paths: ["data"] 13 | 14 | vars: 15 | etl: #stitch or fivetran 16 | criteria_performance_report: #"schema.table" 17 | click_performance_report: #"schema.table" 18 | final_url_performance_report: #"schema.table" 19 | ads_table: #"schema.table" (only for stitch) 20 | ad_groups_table: #"schema.table" (only for stitch) 21 | accounts_table: #"schema.table" (only for stitch) 22 | campaigns_table: #"schema.table" (only for stitch) 23 | adapter_value: #url or criteria 24 | 25 | 26 | -------------------------------------------------------------------------------- /macros/stitch/stitch_adwords_ad_groups.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_ad_groups() %} 2 | 3 | {{ adapter.dispatch('stitch_adwords_ad_groups', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__stitch_adwords_ad_groups() %} 9 | 10 | with ad_groups_source as ( 11 | 12 | select * from {{ var('ad_groups_table') }} 13 | 14 | ), 15 | 16 | ad_groups_renamed as ( 17 | 18 | select 19 | 20 | id as ad_group_id, 21 | name, 22 | adgrouptype as ad_group_type, 23 | baseadgroupid as base_ad_group_id, 24 | basecampaignid as base_campaign_id, 25 | campaignid as campaign_id, 26 | campaignname as campaign_name, 27 | settings, 28 | status, 29 | "_SDC_CUSTOMER_ID" as account_id, 30 | labels 31 | 32 | from ad_groups_source 33 | 34 | ) 35 | 36 | select * from ad_groups_renamed 37 | 38 | {% endmacro %} -------------------------------------------------------------------------------- /models/router/schema.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | models: 3 | - name: adwords_click_performance 4 | columns: 5 | - name: gclid 6 | tests: 7 | - not_null 8 | - unique 9 | - name: adwords_criteria_performance 10 | columns: 11 | - name: id 12 | tests: 13 | - not_null 14 | - unique 15 | - name: adwords_url_performance 16 | columns: 17 | - name: id 18 | tests: 19 | - not_null 20 | - unique 21 | - name: adwords_accounts 22 | columns: 23 | - name: account_id 24 | tests: 25 | - not_null 26 | - unique 27 | - name: adwords_ad_groups 28 | columns: 29 | - name: ad_group_id 30 | tests: 31 | - not_null 32 | - unique 33 | - name: adwords_ads 34 | columns: 35 | - name: ad_id 36 | tests: 37 | - not_null 38 | - unique 39 | - name: adwords_campaigns 40 | columns: 41 | - name: campaign_id 42 | tests: 43 | - not_null 44 | - unique -------------------------------------------------------------------------------- /macros/stitch/stitch_adwords_campaigns.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_campaigns() %} 2 | 3 | {{ adapter.dispatch('stitch_adwords_campaigns', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__stitch_adwords_campaigns() %} 9 | 10 | with campaigns_source as ( 11 | 12 | select * from {{ var('campaigns_table') }} 13 | 14 | ), 15 | 16 | campaigns_renamed as ( 17 | 18 | select 19 | 20 | id as campaign_id, 21 | name, 22 | adservingoptimizationstatus as ad_serving_optimization_status, 23 | advertisingchanneltype as advertising_channel_type, 24 | basecampaignid as base_campaign_id, 25 | campaigntrialtype as campaign_trial_type, 26 | startdate as start_date, 27 | enddate as end_date, 28 | servingstatus as serving_status, 29 | settings, 30 | status, 31 | "_SDC_CUSTOMER_ID" as account_id, 32 | labels 33 | 34 | from campaigns_source 35 | 36 | ) 37 | 38 | select * from campaigns_renamed 39 | 40 | {% endmacro %} -------------------------------------------------------------------------------- /.github/ISSUE_TEMPLATE/bug_report.md: -------------------------------------------------------------------------------- 1 | --- 2 | name: Bug report 3 | about: Report a bug or an issue you've found with this package 4 | title: '' 5 | labels: bug, triage 6 | assignees: '' 7 | 8 | --- 9 | 10 | ### Describe the bug 11 | 14 | 15 | ### Steps to reproduce 16 | 19 | 20 | ### Expected results 21 | 24 | 25 | ### Actual results 26 | 29 | 30 | ### Screenshots and log output 31 | 34 | 35 | ### System information 36 | **The contents of your `packages.yml` file:** 37 | 38 | **Which database are you using dbt with?** 39 | - [ ] postgres 40 | - [ ] redshift 41 | - [ ] bigquery 42 | - [ ] snowflake 43 | - [ ] other (specify: ____________) 44 | 45 | 46 | **The output of `dbt --version`:** 47 | ``` 48 | 49 | ``` 50 | 51 | **The operating system you're using:** 52 | 53 | **The output of `python --version`:** 54 | 55 | ### Additional context 56 | -------------------------------------------------------------------------------- /macros/fivetran/fivetran_adwords_criteria_performance.sql: -------------------------------------------------------------------------------- 1 | {% macro fivetran_adwords_criteria_performance() %} 2 | 3 | {{ adapter.dispatch('fivetran_adwords_criteria_performance', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__fivetran_adwords_criteria_performance() %} 9 | 10 | with criteria_base as ( 11 | 12 | select * from {{ var('criteria_performance_report') }} 13 | 14 | ), 15 | 16 | aggregated as ( 17 | 18 | select 19 | 20 | {{ dbt_utils.surrogate_key ( 21 | [ 22 | 'customer_id', 23 | 'id', 24 | 'ad_group_id', 25 | 'date' 26 | ] 27 | ) }}::varchar as id, 28 | 29 | date::date as date_day, 30 | id as criteria_id, 31 | ad_group_name, 32 | ad_group_id, 33 | ad_group_status as ad_group_state, 34 | campaign_name, 35 | campaign_id, 36 | campaign_status as campaign_state, 37 | customer_id, 38 | _fivetran_synced, 39 | sum(clicks) as clicks, 40 | sum(impressions) as impressions, 41 | sum(cast((cost::float) as numeric(38,6))) as spend 42 | 43 | from criteria_base 44 | {{ dbt_utils.group_by(11) }} 45 | 46 | ), 47 | 48 | ranked as ( 49 | 50 | select 51 | 52 | *, 53 | rank() over (partition by id 54 | order by _fivetran_synced desc) as latest 55 | 56 | from aggregated 57 | 58 | ), 59 | 60 | final as ( 61 | 62 | select * 63 | from ranked 64 | where latest = 1 65 | 66 | ) 67 | 68 | select * from final 69 | 70 | {% endmacro %} -------------------------------------------------------------------------------- /macros/stitch/stitch_adwords_criteria_performance.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_criteria_performance() %} 2 | 3 | {{ adapter.dispatch('stitch_adwords_criteria_performance', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__stitch_adwords_criteria_performance() %} 9 | 10 | with criteria_base as ( 11 | 12 | select * from {{ var('criteria_performance_report') }} 13 | 14 | ), 15 | 16 | aggregated as ( 17 | 18 | select 19 | 20 | {{ dbt_utils.surrogate_key ( 21 | [ 22 | 'customerid', 23 | 'keywordid', 24 | 'adgroupid', 25 | 'day' 26 | ] 27 | ) }}::varchar as id, 28 | 29 | day::date as date_day, 30 | keywordid as criteria_id, 31 | adgroup as ad_group_name, 32 | adgroupid as ad_group_id, 33 | adgroupstate as ad_group_state, 34 | campaign as campaign_name, 35 | campaignid as campaign_id, 36 | campaignstate as campaign_state, 37 | customerid as customer_id, 38 | _sdc_report_datetime, 39 | sum(clicks) as clicks, 40 | sum(impressions) as impressions, 41 | sum(cast((cost::float/1000000::float) as numeric(38,6))) as spend 42 | 43 | from criteria_base 44 | {{ dbt_utils.group_by(11) }} 45 | 46 | ), 47 | 48 | ranked as ( 49 | 50 | select 51 | 52 | *, 53 | rank() over (partition by id 54 | order by _sdc_report_datetime desc) as latest 55 | 56 | from aggregated 57 | 58 | ), 59 | 60 | final as ( 61 | 62 | select * 63 | from ranked 64 | where latest = 1 65 | 66 | ) 67 | 68 | select * from final 69 | 70 | {% endmacro %} -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Google Ads (adwords) 2 | 3 | This package models Google Adwords data. 4 | 5 | [Here](https://developers.google.com/adwords/api/docs/appendix/reports) is info 6 | from Google's API. 7 | 8 | [Here](https://docs.getdbt.com/docs/package-management) is some additional 9 | information about packages in dbt. If you haven't already, you will need to create 10 | a `packages.yml` file in your project and supply the git link from this repository. 11 | 12 | You should then copy the adwords package structure from the `dbt_project.yml` in 13 | this repository into your project's `dbt_project.yml` file and replace the `#` 14 | values with the adwords table names from your warehouse. 15 | 16 | Please note, because several of the models are based on Adwords "reports" which 17 | have a layer of aggregation occurring, the specific fields you select in your ETL 18 | tool are very important in the output of the data. Selecting additional fields 19 | may cause unexpected fan out that these models will not account for. The 20 | recommendation is to track only fields in the models listed in the macros. 21 | 22 | If your team uses UTM parameters for your campaigns, then you should supply the 23 | `adapter_value` var "url". This will query data from the `adwords_url_performance` 24 | model. If your account use gclids or a combination of UTMs and gclids (ie some urls 25 | with have just the gclid) then you should supply the `adapter_value` var "criteria". 26 | This will query data from the `adwords_criteria_performance` report. 27 | 28 | ## Stitch 29 | [Here](https://www.stitchdata.com/docs/integrations/saas/google-adwords#schema) 30 | is info about Stitch's Adwords connector. 31 | 32 | ## Fivetran 33 | [Here](https://fivetran.com/docs/applications/google-ads/setup-guide) 34 | is info about Fivetran's Adwords connector. 35 | 36 | Fivetran does not support the core tables. The core tables are accounts, ad_groups, ads, and campaigns. -------------------------------------------------------------------------------- /macros/fivetran/fivetran_adwords_url_performance.sql: -------------------------------------------------------------------------------- 1 | {% macro fivetran_adwords_url_performance() %} 2 | 3 | {{ adapter.dispatch('fivetran_adwords_url_performance', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__fivetran_adwords_url_performance() %} 9 | 10 | with url_performance_base as ( 11 | 12 | select * from {{ var('final_url_performance_report') }} 13 | 14 | ), 15 | 16 | aggregated as ( 17 | 18 | select 19 | 20 | {{ dbt_utils.surrogate_key ( 21 | [ 22 | 'customer_id', 23 | 'final_urls', 24 | 'date', 25 | 'campaign_id', 26 | 'ad_group_id' 27 | ] 28 | ) }}::varchar as id, 29 | 30 | date::date as date_day, 31 | 32 | {{ dbt_utils.split_part('final_urls', "'?'", 1) }} as base_url, 33 | {{ dbt_utils.get_url_host('final_urls') }} as url_host, 34 | '/' || {{ dbt_utils.get_url_path('final_urls') }} as url_path, 35 | {{ dbt_utils.get_url_parameter('final_urls', 'utm_source') }} as utm_source, 36 | {{ dbt_utils.get_url_parameter('final_urls', 'utm_medium') }} as utm_medium, 37 | {{ dbt_utils.get_url_parameter('final_urls', 'utm_campaign') }} as utm_campaign, 38 | {{ dbt_utils.get_url_parameter('final_urls', 'utm_content') }} as utm_content, 39 | {{ dbt_utils.get_url_parameter('final_urls', 'utm_term') }} as utm_term, 40 | campaign_id, 41 | campaign_name, 42 | ad_group_id, 43 | ad_group_name, 44 | customer_id, 45 | _fivetran_synced as fivetran_synced_at, 46 | 47 | sum(clicks) as clicks, 48 | sum(impressions) as impressions, 49 | sum(cast((cost::float) as numeric(38,6))) as spend 50 | 51 | from url_performance_base 52 | 53 | {{ dbt_utils.group_by(16) }} 54 | 55 | ), 56 | 57 | ranked as ( 58 | 59 | select 60 | 61 | *, 62 | rank() over (partition by id 63 | order by fivetran_synced_at desc) as latest 64 | 65 | from aggregated 66 | 67 | ), 68 | 69 | final as ( 70 | 71 | select * 72 | from ranked 73 | where latest = 1 74 | 75 | ) 76 | 77 | select * from final 78 | 79 | {% endmacro %} -------------------------------------------------------------------------------- /macros/stitch/stitch_adwords_url_performance.sql: -------------------------------------------------------------------------------- 1 | {% macro stitch_adwords_url_performance() %} 2 | 3 | {{ adapter.dispatch('stitch_adwords_url_performance', 'adwords')() }} 4 | 5 | {% endmacro %} 6 | 7 | 8 | {% macro default__stitch_adwords_url_performance() %} 9 | 10 | with url_performance_base as ( 11 | 12 | select * from {{ var('final_url_performance_report') }} 13 | 14 | ), 15 | 16 | aggregated as ( 17 | 18 | select 19 | 20 | {{ dbt_utils.surrogate_key ( 21 | [ 22 | 'customerid', 23 | 'finalurl', 24 | 'day', 25 | 'campaignid', 26 | 'adgroupid' 27 | ] 28 | ) }}::varchar as id, 29 | 30 | day::date as date_day, 31 | 32 | {{ dbt_utils.split_part('finalurl', "'?'", 1) }} as base_url, 33 | {{ dbt_utils.get_url_host('finalurl') }} as url_host, 34 | '/' || {{ dbt_utils.get_url_path('finalurl') }} as url_path, 35 | {{ dbt_utils.get_url_parameter('finalurl', 'utm_source') }} as utm_source, 36 | {{ dbt_utils.get_url_parameter('finalurl', 'utm_medium') }} as utm_medium, 37 | {{ dbt_utils.get_url_parameter('finalurl', 'utm_campaign') }} as utm_campaign, 38 | {{ dbt_utils.get_url_parameter('finalurl', 'utm_content') }} as utm_content, 39 | {{ dbt_utils.get_url_parameter('finalurl', 'utm_term') }} as utm_term, 40 | campaignid as campaign_id, 41 | campaign as campaign_name, 42 | adgroupid as ad_group_id, 43 | adgroup as ad_group_name, 44 | customerid as customer_id, 45 | _sdc_report_datetime, 46 | 47 | sum(clicks) as clicks, 48 | sum(impressions) as impressions, 49 | sum(cast((cost::float/1000000::float) as numeric(38,6))) as spend 50 | 51 | from url_performance_base 52 | 53 | {{ dbt_utils.group_by(16) }} 54 | 55 | ), 56 | 57 | ranked as ( 58 | 59 | select 60 | 61 | *, 62 | rank() over (partition by id 63 | order by _sdc_report_datetime desc) as latest 64 | 65 | from aggregated 66 | 67 | ), 68 | 69 | final as ( 70 | 71 | select * 72 | from ranked 73 | where latest = 1 74 | 75 | ) 76 | 77 | select * from final 78 | 79 | {% endmacro %} -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | APPENDIX: How to apply the Apache License to your work. 179 | 180 | To apply the Apache License to your work, attach the following 181 | boilerplate notice, with the fields enclosed by brackets "{}" 182 | replaced with your own identifying information. (Don't include 183 | the brackets!) The text should be enclosed in the appropriate 184 | comment syntax for the file format. We also recommend that a 185 | file or class name and description of purpose be included on the 186 | same "printed page" as the copyright notice for easier 187 | identification within third-party archives. 188 | 189 | Copyright {yyyy} {name of copyright owner} 190 | 191 | Licensed under the Apache License, Version 2.0 (the "License"); 192 | you may not use this file except in compliance with the License. 193 | You may obtain a copy of the License at 194 | 195 | http://www.apache.org/licenses/LICENSE-2.0 196 | 197 | Unless required by applicable law or agreed to in writing, software 198 | distributed under the License is distributed on an "AS IS" BASIS, 199 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 200 | See the License for the specific language governing permissions and 201 | limitations under the License. 202 | --------------------------------------------------------------------------------