├── .gitignore ├── LICENSE ├── README.md ├── ci_profiles └── profiles.yml ├── dbt_project.yml ├── macros ├── .gitkeep └── get_custom_schema.sql ├── models ├── reporting │ ├── reporting.yml │ └── snowflake_rolling_sum_of_usage.sql └── staging │ ├── aws │ ├── aws.yml │ └── stg_hashmap_aws_costs.sql │ └── snowflake │ ├── snowflake.yml │ ├── stg_hashmap_snowflake_daily_usage.sql │ └── stg_hashmap_snowflake_usage.sql ├── snowflake_setup ├── cloud_cost_monitoring_base.sql ├── service_accounts │ ├── dbt_prod.sql │ ├── dbt_test.sql │ └── sigma_computing.sql └── teardown.sql ├── tests ├── .gitkeep └── staging │ └── snowflake │ └── assert_usage_for_every_day.sql └── workflows ├── ci_prod.yml ├── ci_test.yml └── scheduled_prod.yml /.gitignore: -------------------------------------------------------------------------------- 1 | .DS_Store 2 | logs 3 | target 4 | .user.yml -------------------------------------------------------------------------------- /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 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ![](https://github.com/randypitcherii/cloud_cost_monitoring/workflows/Scheduled%20production%20run/badge.svg) 2 | ![](https://github.com/randypitcherii/cloud_cost_monitoring/workflows/Production%20deployment%20from%20master/badge.svg) 3 | # Cloud Cost Monitoring 4 | This DBT project contains logic for converting raw cost data loaded from Azure, AWS, and GCP into consumable analytics tables. 5 | 6 | Snowflake costs are also gathered from the `ACCOUNT_USAGE` tables. 7 | 8 | ## Snowflake setup 9 | I used the sql in [snowflake_setup](./snowflake_setup) to create the top level databases, warehouse, and permissions that I use for deploying to Snowflake. This is pretty hashmap-specific, so feel free to use / modify / ignore this. -------------------------------------------------------------------------------- /ci_profiles/profiles.yml: -------------------------------------------------------------------------------- 1 | 2 | # For more information on how to configure this file, please see: 3 | # https://docs.getdbt.com/docs/profile 4 | 5 | cloud_cost_monitoring: 6 | target: "{{ env_var('DBT_PROFILE_TARGET') }}" 7 | 8 | outputs: # test and prod are identical, but their target names has significance in different build stages 9 | test: 10 | type: snowflake 11 | account: "{{ env_var('DBT_PROFILE_SNOWFLAKE_ACCOUNT') }}" 12 | 13 | user: "{{ env_var('DBT_PROFILE_USER') }}" 14 | password: "{{ env_var('DBT_PROFILE_PASSWORD') }}" 15 | role: "{{ env_var('DBT_PROFILE_ROLE') }}" 16 | database: "{{ env_var('DBT_PROFILE_DB') }}" 17 | warehouse: "{{ env_var('DBT_PROFILE_WH') }}" 18 | schema: "{{ env_var('DBT_PROFILE_SCHEMA') }}" 19 | 20 | threads: 8 21 | client_session_keep_alive: False 22 | 23 | prod: 24 | type: snowflake 25 | account: "{{ env_var('DBT_PROFILE_SNOWFLAKE_ACCOUNT') }}" 26 | 27 | user: "{{ env_var('DBT_PROFILE_USER') }}" 28 | password: "{{ env_var('DBT_PROFILE_PASSWORD') }}" 29 | role: "{{ env_var('DBT_PROFILE_ROLE') }}" 30 | database: "{{ env_var('DBT_PROFILE_DB') }}" 31 | warehouse: "{{ env_var('DBT_PROFILE_WH') }}" 32 | schema: "{{ env_var('DBT_PROFILE_SCHEMA') }}" 33 | 34 | threads: 8 35 | client_session_keep_alive: False 36 | -------------------------------------------------------------------------------- /dbt_project.yml: -------------------------------------------------------------------------------- 1 | 2 | # Name your package! Package names should contain only lowercase characters 3 | # and underscores. A good package name should reflect your organization's 4 | # name or the intended use of these models 5 | name: 'cloud_cost_monitoring' 6 | version: '0.0.1' 7 | 8 | # This setting configures which "profile" dbt uses for this project. Profiles contain 9 | # database connection information, and should be configured in the ~/.dbt/profiles.yml file 10 | profile: 'cloud_cost_monitoring' 11 | 12 | # These configurations specify where dbt should look for different types of files. 13 | # The `source-paths` config, for example, states that source models can be found 14 | # in the "models/" directory. You probably won't need to change these! 15 | source-paths: ["models"] 16 | analysis-paths: ["analysis"] 17 | test-paths: ["tests"] 18 | data-paths: ["data"] 19 | macro-paths: ["macros"] 20 | 21 | target-path: "target" # directory which will store compiled SQL files 22 | clean-targets: # directories to be removed by `dbt clean` 23 | - "target" 24 | - "dbt_modules" 25 | 26 | models: 27 | cloud_cost_monitoring: 28 | staging: 29 | schema: staging 30 | materialized: view 31 | reporting: 32 | schema: reporting 33 | materialized: table 34 | -------------------------------------------------------------------------------- /macros/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/randypitcherii/cloud_cost_monitoring/28ecffc078f78bbd926aac975a1b246b22399ad8/macros/.gitkeep -------------------------------------------------------------------------------- /macros/get_custom_schema.sql: -------------------------------------------------------------------------------- 1 | {% macro generate_schema_name(custom_schema_name, node) -%} 2 | {%- set default_schema = target.schema -%} 3 | 4 | {%- if custom_schema_name is none -%} 5 | {{ default_schema }} 6 | {%- elif 'prod' == target.name -%} 7 | {{ custom_schema_name | trim }} 8 | {%- else -%} 9 | {{ default_schema }}_{{ custom_schema_name | trim }} 10 | {%- endif -%} 11 | {%- endmacro %} -------------------------------------------------------------------------------- /models/reporting/reporting.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | - name: snowflake_rolling_sum_of_usage 5 | description: This relation contains 30-day rolling SUM of total metered credit usage for the hashmap AWS-flavored Snowflake instance. 6 | columns: 7 | - name: calculated_on 8 | description: This is the date that usage was calculated on, going backwards 30 days 9 | tests: 10 | - not_null 11 | - unique 12 | - name: credits_used_last_30_days 13 | description: This is the SUM of credits used over the last 30 days 14 | tests: 15 | - not_null -------------------------------------------------------------------------------- /models/reporting/snowflake_rolling_sum_of_usage.sql: -------------------------------------------------------------------------------- 1 | with daily_usage as ( 2 | select * from {{ ref('stg_hashmap_snowflake_daily_usage') }} 3 | ), 4 | 5 | snowflake_rolling_sum_of_usage as ( 6 | select 7 | calculated_on, 8 | sum(credits_used) over (order by calculated_on rows between 29 preceding and current row) as credits_used_last_30_days 9 | from 10 | daily_usage 11 | order by 12 | calculated_on desc 13 | ) 14 | 15 | select * from snowflake_rolling_sum_of_usage -------------------------------------------------------------------------------- /models/staging/aws/aws.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | sources: 4 | - name: aws_costs 5 | database: fivetran_db 6 | schema: hashmap_aws_cost_monitoring 7 | loader: fivetran # informational only (free text) 8 | loaded_at_field: _fivetran_synced # configure for all sources 9 | 10 | freshness: 11 | warn_after: {count: 12, period: hour} 12 | error_after: {count: 24, period: hour} 13 | 14 | tables: 15 | - name: hashmap_aws_costs 16 | loaded_at_field: updated_at # used to calculate freshness -------------------------------------------------------------------------------- /models/staging/aws/stg_hashmap_aws_costs.sql: -------------------------------------------------------------------------------- 1 | with raw_costs as ( 2 | select * from {{ source('aws_costs', 'hashmap_aws_costs') }} 3 | ) 4 | 5 | select * from raw_costs -------------------------------------------------------------------------------- /models/staging/snowflake/snowflake.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | sources: 4 | - name: snowflake_usage 5 | database: fivetran_db 6 | schema: hashmap_snowflake_usage 7 | loader: fivetran # informational only (free text) 8 | loaded_at_field: ingestion_time # used to calculate freshness 9 | 10 | freshness: 11 | warn_after: {count: 24, period: hour} 12 | 13 | tables: 14 | - name: query_history 15 | - name: warehouse_metering_history 16 | 17 | models: 18 | - name: stg_hashmap_snowflake_daily_usage 19 | description: This relation contains daily total metered credit usage for the hashmap AWS-flavored Snowflake instance. 20 | columns: 21 | - name: calculated_on 22 | description: This is the date that usage was calculated on. 23 | tests: 24 | - not_null 25 | - unique 26 | - name: credits_used 27 | description: This is the SUM of credits used on a given day. 28 | tests: 29 | - not_null -------------------------------------------------------------------------------- /models/staging/snowflake/stg_hashmap_snowflake_daily_usage.sql: -------------------------------------------------------------------------------- 1 | // prehook to generate a fresh sequence for building a proper daily_usage table 2 | {{ 3 | config( 4 | pre_hook="CREATE OR REPLACE SEQUENCE {{target.database}}.{{this.schema}}.DAILY_USAGE_SEQ START=0 INCREMENT=1" 5 | ) 6 | }} 7 | 8 | with usage as ( 9 | select * from {{ ref('stg_hashmap_snowflake_usage') }} 10 | ), 11 | 12 | reported_usage_date_range as ( 13 | select 14 | min(start_time) as min_date, 15 | max(start_time) as max_date 16 | from 17 | usage 18 | ), 19 | 20 | filler_daily_usage as ( 21 | select 22 | 0 as credits_used, 23 | dateadd( 24 | day, -{{target.database}}.{{this.schema}}.DAILY_USAGE_SEQ.nextval, current_timestamp 25 | ) as start_time 26 | from 27 | table(generator(rowcount => 1000)) // this will break in the future 28 | where 29 | start_time >= (select min_date from reported_usage_date_range) and 30 | start_time <= (select max_date from reported_usage_date_range) 31 | ), 32 | 33 | combined_usage as ( 34 | select usage.credits_used, usage.start_time from usage 35 | union all 36 | select fdu.credits_used, fdu.start_time from filler_daily_usage fdu 37 | ), 38 | 39 | daily_usage as ( 40 | select 41 | sum(credits_used) as credits_used, 42 | date_trunc('day', start_time)::date as calculated_on 43 | from 44 | combined_usage 45 | group by 46 | calculated_on 47 | order by 48 | calculated_on desc 49 | ) 50 | 51 | select * from daily_usage -------------------------------------------------------------------------------- /models/staging/snowflake/stg_hashmap_snowflake_usage.sql: -------------------------------------------------------------------------------- 1 | with usage as ( 2 | select 3 | * 4 | from 5 | {{ source('snowflake_usage', 'warehouse_metering_history') }} 6 | ) 7 | 8 | select * from usage -------------------------------------------------------------------------------- /snowflake_setup/cloud_cost_monitoring_base.sql: -------------------------------------------------------------------------------- 1 | /** 2 | This script creates the top-level objects for the 3 | Cloud Cost Monitoring initiative in Snowflake. It also 4 | creates corresponding object access roles to assign to 5 | business function roles as needed. 6 | **/ 7 | //============================================================================= 8 | // create databases 9 | //============================================================================= 10 | USE ROLE SYSADMIN; 11 | 12 | // Databases 13 | CREATE DATABASE CLOUD_COST_MONITORING_DEV; // local dbt targets this db from developer machines 14 | CREATE DATABASE CLOUD_COST_MONITORING_TEST; // CI from pull requests happens here 15 | CREATE DATABASE CLOUD_COST_MONITORING_PROD; // CI from merges to master happens here 16 | 17 | // Reporting schema. This must exist now for reporter permissions. 18 | CREATE SCHEMA CLOUD_COST_MONITORING_PROD.REPORTING; 19 | //============================================================================= 20 | 21 | 22 | //============================================================================= 23 | // create warehouses 24 | //============================================================================= 25 | USE ROLE SYSADMIN; 26 | 27 | // dev warehouse 28 | CREATE WAREHOUSE 29 | CLOUD_COST_MONITORING_DEV_WH 30 | COMMENT='Warehouse for powering developer activities for the cloud cost monitoring project' 31 | WAREHOUSE_SIZE=XSMALL 32 | AUTO_SUSPEND=60 33 | INITIALLY_SUSPENDED=TRUE; 34 | //============================================================================= 35 | 36 | 37 | //============================================================================= 38 | // create object access roles for databases 39 | //============================================================================= 40 | USE ROLE SECURITYADMIN; 41 | 42 | // dev roles 43 | CREATE ROLE CLOUD_COST_MONITORING_DEV_READ_WRITE; 44 | 45 | // test roles 46 | CREATE ROLE CLOUD_COST_MONITORING_TEST_READ_WRITE; 47 | 48 | // prod roles 49 | CREATE ROLE CLOUD_COST_MONITORING_PROD_READ_WRITE; 50 | 51 | // prod reporting roles 52 | CREATE ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 53 | 54 | // grant all roles to sysadmin (always do this) 55 | GRANT ROLE CLOUD_COST_MONITORING_DEV_READ_WRITE TO ROLE SYSADMIN; 56 | GRANT ROLE CLOUD_COST_MONITORING_TEST_READ_WRITE TO ROLE SYSADMIN; 57 | GRANT ROLE CLOUD_COST_MONITORING_PROD_READ_WRITE TO ROLE SYSADMIN; 58 | GRANT ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ TO ROLE SYSADMIN; 59 | //============================================================================= 60 | 61 | 62 | //============================================================================= 63 | // create object access roles for warehouses 64 | //============================================================================= 65 | USE ROLE SECURITYADMIN; 66 | 67 | // dev roles 68 | CREATE ROLE CLOUD_COST_MONITORING_DEV_WH_ALL; 69 | 70 | // grant all roles to sysadmin (always do this) 71 | GRANT ROLE CLOUD_COST_MONITORING_DEV_WH_ALL TO ROLE SYSADMIN; 72 | //============================================================================= 73 | 74 | 75 | //============================================================================= 76 | // grant privileges to object access roles 77 | //============================================================================= 78 | USE ROLE SECURITYADMIN; 79 | 80 | // dev permissions 81 | GRANT CREATE SCHEMA, USAGE ON DATABASE CLOUD_COST_MONITORING_DEV TO ROLE CLOUD_COST_MONITORING_DEV_READ_WRITE; 82 | GRANT ALL PRIVILEGES ON WAREHOUSE CLOUD_COST_MONITORING_DEV_WH TO ROLE CLOUD_COST_MONITORING_DEV_WH_ALL; 83 | 84 | // test permissions 85 | GRANT CREATE SCHEMA, USAGE ON DATABASE CLOUD_COST_MONITORING_TEST TO ROLE CLOUD_COST_MONITORING_TEST_READ_WRITE; 86 | 87 | // prod permissions 88 | GRANT CREATE SCHEMA, USAGE ON DATABASE CLOUD_COST_MONITORING_PROD TO ROLE CLOUD_COST_MONITORING_PROD_READ_WRITE; 89 | 90 | // transfer reporting schema ownership 91 | USE ROLE SYSADMIN; 92 | GRANT OWNERSHIP ON SCHEMA CLOUD_COST_MONITORING_PROD.REPORTING TO ROLE CLOUD_COST_MONITORING_PROD_READ_WRITE; 93 | 94 | // reporting permissions 95 | USE ROLE SECURITYADMIN; 96 | GRANT USAGE ON DATABASE CLOUD_COST_MONITORING_PROD TO ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 97 | GRANT USAGE ON SCHEMA CLOUD_COST_MONITORING_PROD.REPORTING TO ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 98 | GRANT SELECT ON ALL TABLES IN SCHEMA CLOUD_COST_MONITORING_PROD.REPORTING TO ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 99 | GRANT SELECT ON FUTURE TABLES IN SCHEMA CLOUD_COST_MONITORING_PROD.REPORTING TO ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 100 | GRANT SELECT ON ALL VIEWS IN SCHEMA CLOUD_COST_MONITORING_PROD.REPORTING TO ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 101 | GRANT SELECT ON FUTURE VIEWS IN SCHEMA CLOUD_COST_MONITORING_PROD.REPORTING TO ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 102 | //============================================================================= 103 | 104 | 105 | //============================================================================= 106 | // create business function roles and grant access to object access roles 107 | //============================================================================= 108 | USE ROLE SECURITYADMIN; 109 | 110 | // transformer roles 111 | CREATE ROLE CLOUD_COST_MONITORING_DEV_TRANSFORMER; 112 | 113 | // grant all roles to sysadmin (always do this) 114 | GRANT ROLE CLOUD_COST_MONITORING_DEV_TRANSFORMER TO ROLE SYSADMIN; 115 | 116 | // dev OA roles 117 | GRANT ROLE CLOUD_COST_MONITORING_DEV_READ_WRITE TO ROLE CLOUD_COST_MONITORING_DEV_TRANSFORMER; 118 | GRANT ROLE CLOUD_COST_MONITORING_DEV_WH_ALL TO ROLE CLOUD_COST_MONITORING_DEV_TRANSFORMER; 119 | GRANT ROLE FIVETRAN_READ_ROLE TO ROLE CLOUD_COST_MONITORING_DEV_TRANSFORMER; 120 | //============================================================================= -------------------------------------------------------------------------------- /snowflake_setup/service_accounts/dbt_prod.sql: -------------------------------------------------------------------------------- 1 | //============================================================================= 2 | // create warehouses 3 | //============================================================================= 4 | USE ROLE SYSADMIN; 5 | 6 | // prod warehouse 7 | CREATE WAREHOUSE 8 | CLOUD_COST_MONITORING_PROD_WH 9 | COMMENT='Warehouse for powering CI prod activities for the cloud cost monitoring project' 10 | WAREHOUSE_SIZE=XSMALL 11 | AUTO_SUSPEND=60 12 | INITIALLY_SUSPENDED=TRUE; 13 | //============================================================================= 14 | 15 | 16 | //============================================================================= 17 | // create object access roles for warehouses 18 | //============================================================================= 19 | USE ROLE SECURITYADMIN; 20 | 21 | // prod roles for ci (also not for humans) 22 | CREATE ROLE CLOUD_COST_MONITORING_PROD_WH_USAGE; 23 | 24 | // grant all roles to sysadmin (always do this) 25 | GRANT ROLE CLOUD_COST_MONITORING_PROD_WH_USAGE TO ROLE SYSADMIN; 26 | //============================================================================= 27 | 28 | 29 | //============================================================================= 30 | // grant privileges to object access roles 31 | //============================================================================= 32 | USE ROLE SECURITYADMIN; 33 | 34 | // prod permissions 35 | GRANT USAGE ON WAREHOUSE CLOUD_COST_MONITORING_PROD_WH TO ROLE CLOUD_COST_MONITORING_PROD_WH_USAGE; 36 | //============================================================================= 37 | 38 | 39 | //============================================================================= 40 | // create business function roles and grant access to object access roles 41 | //============================================================================= 42 | USE ROLE SECURITYADMIN; 43 | 44 | // transformer roles 45 | CREATE ROLE CLOUD_COST_MONITORING_PROD_TRANSFORMER; 46 | 47 | // grant all roles to sysadmin (always do this) 48 | GRANT ROLE CLOUD_COST_MONITORING_PROD_TRANSFORMER TO ROLE SYSADMIN; 49 | 50 | // prod OA roles 51 | GRANT ROLE CLOUD_COST_MONITORING_PROD_READ_WRITE TO ROLE CLOUD_COST_MONITORING_PROD_TRANSFORMER; 52 | GRANT ROLE CLOUD_COST_MONITORING_PROD_WH_USAGE TO ROLE CLOUD_COST_MONITORING_PROD_TRANSFORMER; 53 | GRANT ROLE FIVETRAN_READ_ROLE TO ROLE CLOUD_COST_MONITORING_PROD_TRANSFORMER; 54 | //============================================================================= 55 | 56 | 57 | //============================================================================= 58 | // create service account 59 | //============================================================================= 60 | USE ROLE SECURITYADMIN; 61 | 62 | // create service account 63 | CREATE USER 64 | DBT_CLOUD_COST_MONITORING_PROD_SERVICE_ACCOUNT 65 | PASSWORD = 'my cool password here' // use your own password 66 | COMMENT = 'Service account for DBT CI/CD in the prod environment of the Cloud Cost Monitoring project.' 67 | DEFAULT_WAREHOUSE = CLOUD_COST_MONITORING_PROD_WH 68 | DEFAULT_ROLE = CLOUD_COST_MONITORING_PROD_TRANSFORMER 69 | MUST_CHANGE_PASSWORD = FALSE; 70 | 71 | // grant permissions to service account 72 | GRANT ROLE CLOUD_COST_MONITORING_PROD_TRANSFORMER TO USER DBT_CLOUD_COST_MONITORING_PROD_SERVICE_ACCOUNT; 73 | //============================================================================= 74 | -------------------------------------------------------------------------------- /snowflake_setup/service_accounts/dbt_test.sql: -------------------------------------------------------------------------------- 1 | //============================================================================= 2 | // create warehouses 3 | //============================================================================= 4 | USE ROLE SYSADMIN; 5 | 6 | // test warehouse 7 | CREATE WAREHOUSE 8 | CLOUD_COST_MONITORING_TEST_WH 9 | COMMENT='Warehouse for powering CI test activities for the cloud cost monitoring project' 10 | WAREHOUSE_SIZE=XSMALL 11 | AUTO_SUSPEND=60 12 | INITIALLY_SUSPENDED=TRUE; 13 | //============================================================================= 14 | 15 | 16 | //============================================================================= 17 | // create object access roles for warehouses 18 | //============================================================================= 19 | USE ROLE SECURITYADMIN; 20 | 21 | // test for ci (not for humans) 22 | CREATE ROLE CLOUD_COST_MONITORING_TEST_WH_USAGE; 23 | 24 | // grant all roles to sysadmin (always do this) 25 | GRANT ROLE CLOUD_COST_MONITORING_TEST_WH_USAGE TO ROLE SYSADMIN; 26 | //============================================================================= 27 | 28 | 29 | //============================================================================= 30 | // grant privileges to object access roles 31 | //============================================================================= 32 | USE ROLE SECURITYADMIN; 33 | 34 | // test permissions 35 | GRANT USAGE ON WAREHOUSE CLOUD_COST_MONITORING_TEST_WH TO ROLE CLOUD_COST_MONITORING_TEST_WH_USAGE; 36 | //============================================================================= 37 | 38 | 39 | //============================================================================= 40 | // create business function roles and grant access to object access roles 41 | //============================================================================= 42 | USE ROLE SECURITYADMIN; 43 | 44 | // transformer roles 45 | CREATE ROLE CLOUD_COST_MONITORING_TEST_TRANSFORMER; 46 | 47 | // grant all roles to sysadmin (always do this) 48 | GRANT ROLE CLOUD_COST_MONITORING_TEST_TRANSFORMER TO ROLE SYSADMIN; 49 | 50 | // test OA roles 51 | GRANT ROLE CLOUD_COST_MONITORING_TEST_READ_WRITE TO ROLE CLOUD_COST_MONITORING_TEST_TRANSFORMER; 52 | GRANT ROLE CLOUD_COST_MONITORING_TEST_WH_USAGE TO ROLE CLOUD_COST_MONITORING_TEST_TRANSFORMER; 53 | GRANT ROLE FIVETRAN_READ_ROLE TO ROLE CLOUD_COST_MONITORING_TEST_TRANSFORMER; 54 | //============================================================================= 55 | 56 | 57 | //============================================================================= 58 | // create service account 59 | //============================================================================= 60 | USE ROLE SECURITYADMIN; 61 | 62 | // create service account 63 | CREATE USER 64 | DBT_CLOUD_COST_MONITORING_TEST_SERVICE_ACCOUNT 65 | PASSWORD = 'my cool password here' // use your own password 66 | COMMENT = 'Service account for DBT CI/CD in the test environment of the Cloud Cost Monitoring project.' 67 | DEFAULT_WAREHOUSE = CLOUD_COST_MONITORING_TEST_WH 68 | DEFAULT_ROLE = CLOUD_COST_MONITORING_TEST_TRANSFORMER 69 | MUST_CHANGE_PASSWORD = FALSE; 70 | 71 | // grant permissions to service account 72 | GRANT ROLE CLOUD_COST_MONITORING_TEST_TRANSFORMER TO USER DBT_CLOUD_COST_MONITORING_TEST_SERVICE_ACCOUNT; 73 | //============================================================================= 74 | -------------------------------------------------------------------------------- /snowflake_setup/service_accounts/sigma_computing.sql: -------------------------------------------------------------------------------- 1 | //============================================================================= 2 | // create warehouses 3 | //============================================================================= 4 | USE ROLE SYSADMIN; 5 | 6 | // reporting warehouse 7 | CREATE WAREHOUSE 8 | SIGMA_CLOUD_COST_MONITORING_REPORTING_WH 9 | COMMENT='Warehouse for powering reporting queries from Sigma' 10 | WAREHOUSE_SIZE=XSMALL 11 | AUTO_SUSPEND=60 12 | INITIALLY_SUSPENDED=TRUE; 13 | //============================================================================= 14 | 15 | 16 | //============================================================================= 17 | // create object access roles for warehouses 18 | //============================================================================= 19 | USE ROLE SECURITYADMIN; 20 | 21 | // reporting roles for the sigma service account 22 | CREATE ROLE SIGMA_CLOUD_COST_MONITORING_REPORTING_WH_USAGE; 23 | 24 | // grant all roles to sysadmin (always do this) 25 | GRANT ROLE SIGMA_CLOUD_COST_MONITORING_REPORTING_WH_USAGE TO ROLE SYSADMIN; 26 | //============================================================================= 27 | 28 | 29 | //============================================================================= 30 | // grant privileges to object access roles 31 | //============================================================================= 32 | USE ROLE SECURITYADMIN; 33 | 34 | // reporting permissions 35 | GRANT USAGE ON WAREHOUSE SIGMA_CLOUD_COST_MONITORING_REPORTING_WH TO ROLE SIGMA_CLOUD_COST_MONITORING_REPORTING_WH_USAGE; 36 | //============================================================================= 37 | 38 | 39 | //============================================================================= 40 | // create business function roles and grant access to object access roles 41 | //============================================================================= 42 | USE ROLE SECURITYADMIN; 43 | 44 | // reporter roles 45 | CREATE ROLE SIGMA_CLOUD_COST_MONITORING_REPORTER; 46 | GRANT ROLE SIGMA_CLOUD_COST_MONITORING_REPORTER TO ROLE SYSADMIN; 47 | 48 | // grant OA roles to BF roles 49 | GRANT ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ TO ROLE SIGMA_CLOUD_COST_MONITORING_REPORTER; 50 | GRANT ROLE SIGMA_CLOUD_COST_MONITORING_REPORTING_WH_USAGE TO ROLE SIGMA_CLOUD_COST_MONITORING_REPORTER; 51 | //============================================================================= 52 | 53 | 54 | //============================================================================= 55 | // create service account 56 | //============================================================================= 57 | USE ROLE SECURITYADMIN; 58 | 59 | // create service account 60 | CREATE USER 61 | SIGMA_CLOUD_COST_MONITORING_SERVICE_ACCOUNT 62 | PASSWORD = 'my cool password here' // use your own password 63 | COMMENT = 'Service account for connecting Sigma Computing to Snowflake for Cloud Cost Monitoring reports.' 64 | DEFAULT_WAREHOUSE = SIGMA_CLOUD_COST_MONITORING_REPORTING_WH 65 | DEFAULT_ROLE = SIGMA_CLOUD_COST_MONITORING_REPORTER 66 | MUST_CHANGE_PASSWORD = FALSE; 67 | 68 | // grant permissions to service account 69 | GRANT ROLE SIGMA_CLOUD_COST_MONITORING_REPORTER TO USER SIGMA_CLOUD_COST_MONITORING_SERVICE_ACCOUNT; 70 | //============================================================================= 71 | -------------------------------------------------------------------------------- /snowflake_setup/teardown.sql: -------------------------------------------------------------------------------- 1 | USE ROLE SYSADMIN; 2 | DROP DATABASE CLOUD_COST_MONITORING_DEV; 3 | DROP DATABASE CLOUD_COST_MONITORING_PROD; 4 | DROP DATABASE CLOUD_COST_MONITORING_TEST; 5 | DROP WAREHOUSE CLOUD_COST_MONITORING_DEV_WH; 6 | DROP WAREHOUSE CLOUD_COST_MONITORING_PROD_WH; 7 | DROP WAREHOUSE CLOUD_COST_MONITORING_TEST_WH; 8 | DROP WAREHOUSE SIGMA_CLOUD_COST_MONITORING_REPORTING_WH; 9 | 10 | USE ROLE SECURITYADMIN; 11 | DROP ROLE CLOUD_COST_MONITORING_DEV_READ_WRITE; 12 | DROP ROLE CLOUD_COST_MONITORING_DEV_TRANSFORMER; 13 | DROP ROLE CLOUD_COST_MONITORING_DEV_TRANSFORMER; 14 | DROP ROLE CLOUD_COST_MONITORING_DEV_WH_ALL; 15 | DROP ROLE CLOUD_COST_MONITORING_PROD_READ_WRITE; 16 | DROP ROLE CLOUD_COST_MONITORING_PROD_REPORTING_READ; 17 | DROP ROLE CLOUD_COST_MONITORING_PROD_TRANSFORMER; 18 | DROP ROLE CLOUD_COST_MONITORING_PROD_WH_USAGE; 19 | DROP ROLE CLOUD_COST_MONITORING_TEST_READ_WRITE; 20 | DROP ROLE CLOUD_COST_MONITORING_TEST_TRANSFORMER; 21 | DROP ROLE CLOUD_COST_MONITORING_TEST_WH_USAGE; 22 | DROP ROLE SIGMA_CLOUD_COST_MONITORING_REPORTER; 23 | DROP ROLE SIGMA_CLOUD_COST_MONITORING_REPORTING_WH_USAGE; 24 | DROP USER DBT_CLOUD_COST_MONITORING_PROD_SERVICE_ACCOUNT; 25 | DROP USER DBT_CLOUD_COST_MONITORING_PROD_SERVICE_ACCOUNT; 26 | DROP USER SIGMA_CLOUD_COST_MONITORING_SERVICE_ACCOUNT; -------------------------------------------------------------------------------- /tests/.gitkeep: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/randypitcherii/cloud_cost_monitoring/28ecffc078f78bbd926aac975a1b246b22399ad8/tests/.gitkeep -------------------------------------------------------------------------------- /tests/staging/snowflake/assert_usage_for_every_day.sql: -------------------------------------------------------------------------------- 1 | {{ config(severity='warn') }} 2 | 3 | with data as ( 4 | select 5 | count(*) as num_rows, 6 | min(calculated_on) as first_date, 7 | max(calculated_on) as last_date, 8 | (last_date - first_date) + 1 as num_days 9 | from 10 | {{ ref('stg_hashmap_snowflake_daily_usage') }} 11 | ), 12 | 13 | validation as ( 14 | select 15 | * 16 | from 17 | data 18 | where 19 | num_rows != num_days 20 | ) 21 | 22 | select * from validation 23 | -------------------------------------------------------------------------------- /workflows/ci_prod.yml: -------------------------------------------------------------------------------- 1 | name: Production deployment from master 2 | 3 | on: 4 | push: 5 | branches: 6 | - master 7 | 8 | env: 9 | DBT_PROFILE_TARGET: prod 10 | DBT_PROFILE_SNOWFLAKE_ACCOUNT: ${{ secrets.DBT_PROFILE_SNOWFLAKE_ACCOUNT }} 11 | DBT_PROFILE_USER: ${{ secrets.DBT_PROFILE_PROD_USER }} 12 | DBT_PROFILE_PASSWORD: ${{ secrets.DBT_PROFILE_PROD_PASSWORD }} 13 | DBT_PROFILE_ROLE: CLOUD_COST_MONITORING_PROD_TRANSFORMER 14 | DBT_PROFILE_DB: CLOUD_COST_MONITORING_PROD 15 | DBT_PROFILE_SCHEMA: STAGING 16 | DBT_PROFILE_WH: CLOUD_COST_MONITORING_PROD_WH 17 | 18 | jobs: 19 | prod: 20 | runs-on: ubuntu-latest 21 | 22 | steps: 23 | - name: Checkout branch 24 | uses: actions/checkout@v2 25 | 26 | - name: Install Python 3.7 27 | uses: actions/setup-python@v1 28 | with: 29 | python-version: 3.7 30 | 31 | - name: Install DBT 32 | run: | 33 | python -m pip install --upgrade pip 34 | pip install dbt 35 | 36 | - name: Deploy 37 | run: | 38 | dbt run --profiles-dir ./ci_profiles 39 | dbt test --profiles-dir ./ci_profiles 40 | -------------------------------------------------------------------------------- /workflows/ci_test.yml: -------------------------------------------------------------------------------- 1 | name: Test deployment from a PR 2 | 3 | on: pull_request 4 | 5 | env: 6 | DBT_PROFILE_TARGET: test 7 | DBT_PROFILE_SNOWFLAKE_ACCOUNT: ${{ secrets.DBT_PROFILE_SNOWFLAKE_ACCOUNT }} 8 | DBT_PROFILE_USER: ${{ secrets.DBT_PROFILE_TEST_USER }} 9 | DBT_PROFILE_PASSWORD: ${{ secrets.DBT_PROFILE_TEST_PASSWORD }} 10 | DBT_PROFILE_ROLE: CLOUD_COST_MONITORING_TEST_TRANSFORMER 11 | DBT_PROFILE_DB: CLOUD_COST_MONITORING_TEST 12 | DBT_PROFILE_WH: CLOUD_COST_MONITORING_TEST_WH 13 | 14 | jobs: 15 | prod: 16 | runs-on: ubuntu-latest 17 | 18 | steps: 19 | - name: Checkout branch 20 | uses: actions/checkout@v2 21 | 22 | - name: Install Python 3.7 23 | uses: actions/setup-python@v1 24 | with: 25 | python-version: 3.7 26 | 27 | - name: Install DBT 28 | run: | 29 | python -m pip install --upgrade pip 30 | pip install dbt 31 | 32 | - name: Deploy 33 | run: | 34 | export DBT_PROFILE_SCHEMA=pr_$(date +%s) 35 | dbt run --profiles-dir ./ci_profiles 36 | dbt test --profiles-dir ./ci_profiles 37 | -------------------------------------------------------------------------------- /workflows/scheduled_prod.yml: -------------------------------------------------------------------------------- 1 | name: Scheduled production run 2 | 3 | on: 4 | schedule: 5 | - cron: '0 */1 * * *' # Run every hour 6 | 7 | env: 8 | DBT_PROFILE_TARGET: prod 9 | DBT_PROFILE_SNOWFLAKE_ACCOUNT: ${{ secrets.DBT_PROFILE_SNOWFLAKE_ACCOUNT }} 10 | DBT_PROFILE_USER: ${{ secrets.DBT_PROFILE_PROD_USER }} 11 | DBT_PROFILE_PASSWORD: ${{ secrets.DBT_PROFILE_PROD_PASSWORD }} 12 | DBT_PROFILE_ROLE: CLOUD_COST_MONITORING_PROD_TRANSFORMER 13 | DBT_PROFILE_DB: CLOUD_COST_MONITORING_PROD 14 | DBT_PROFILE_SCHEMA: STAGING 15 | DBT_PROFILE_WH: CLOUD_COST_MONITORING_PROD_WH 16 | 17 | jobs: 18 | prod: 19 | runs-on: ubuntu-latest 20 | 21 | steps: 22 | - name: Checkout branch 23 | uses: actions/checkout@v2 24 | 25 | - name: Install Python 3.7 26 | uses: actions/setup-python@v1 27 | with: 28 | python-version: 3.7 29 | 30 | - name: Install DBT 31 | run: | 32 | python -m pip install --upgrade pip 33 | pip install dbt 34 | 35 | - name: Deploy 36 | run: | 37 | dbt run --profiles-dir ./ci_profiles 38 | --------------------------------------------------------------------------------