├── Chapter_01 ├── 01_01_Intro_to_SQL.sql ├── 01_02_SQL_Basics.sql ├── 01_03_Setup_Snowflake.sql ├── 01_04_Query_syntax.sql ├── 01_05_JOIN_clause.sql └── 01_06_Window_functions.sql ├── Chapter_03 └── 03_04_Use_cases.sql ├── Chapter_05 ├── README.md ├── data │ └── ABC_Bank_PORTFOLIO__2021-04-09.csv ├── dbt │ ├── 05_03_v1__source_abc_bank.yml │ ├── 05_03_v2__source_abc_bank.yml │ ├── 05_04_v1__POSITION_ABC_BANK.sql │ └── 05_05_v1__dbt_project.yml └── snowflake │ ├── 05_01_Setup_Portfolio_tracking_project.sql │ └── 05_02_Setup_ABC_Bank_Landing_table.sql ├── Chapter_06 ├── csv │ ├── country_ISO_3166.csv │ ├── currency_ISO_4217.csv │ └── exchange.csv ├── dbt │ ├── 06_01_v2__dbt_project.yml │ ├── 06_02_v1__STG_ABC_BANK_POSITION.sql │ ├── 06_02_v2__STG_ABC_BANK_POSITION.sql │ ├── 06_02_v3__STG_ABC_BANK_POSITION.sql │ ├── 06_03_v1__REF_POSITION_ABC_BANK.sql │ ├── 06_03_v2__REF_POSITION_ABC_BANK.sql │ ├── 06_04_v1__FACT_POSITION.sql │ ├── 06_05_v1__SNSH_ABC_BANK_POSITION.sql │ ├── 06_07_v1__ABC_Bank_SECURITY_INFO.csv │ ├── 06_08_v1__STG_ABC_BANK_SECURITY_INFO.sql │ ├── 06_09_v1__SNSH_ABC_BANK_SECURITY_INFO.sql │ ├── 06_10_v1__REF_ABC_BANK_SECURITY_INFO.sql │ ├── 06_11_v1__DIM_SECURITY.sql │ ├── 06_12_v1__source_seed.yml │ ├── 06_13_v1__source_abc_bank.yml │ ├── 06_14_v1__refined.yml │ └── 06_15_v1__README.md └── patterns │ └── 06_06_v1__STG_Model.sql ├── Chapter_07 └── dbt │ ├── 07_01_v1__this_with_filter.sql │ ├── 07_02_v1__current_from_snapshot.sql │ ├── 07_02_v2__current_from_snapshot.sql │ ├── 07_03_v1__REF_POSITION_ABC_BANK.sql │ ├── 07_03_v2__REF_POSITION_ABC_BANK.sql │ ├── 07_04_v1__REF_ABC_BANK_SECURITY_INFO.sql │ └── 07_05_v1__STG_ABC_BANK_POSITION.sql ├── Chapter_09 └── dbt │ ├── 09_01_v1__has_default_key.sql │ └── 09_02_v1__warn_on_multiple_default_key.sql ├── Chapter_12 └── dbt │ ├── 12_02_v1__exp_portfolio_report.md │ └── 12_02_v1__exp_portfolio_report.yml ├── Chapter_13 └── dbt │ ├── macros │ ├── 13_01_v1__save_history.sql │ ├── 13_01_v1__save_history__outline.sql │ └── 13_02_v1__current_from_history.sql │ └── models │ ├── 13_03_v1__HIST_ABC_BANK_POSITION.sql │ └── 13_04_v1__HIST_ABC_BANK_SECURITY_INFO.sql ├── Chapter_14 └── dbt │ ├── analysis │ ├── 14_12_v1__SRC_POSITION_init.sql │ └── 14_13_v1__SRC_POSITION_v2.sql │ ├── macros │ ├── delivery │ │ └── self_completing_dimension.sql │ └── migrations │ │ ├── 14_10_v1__run_migrations.sql │ │ ├── 14_10_v2__run_migrations.sql │ │ ├── 14_11_v1__V003_drop_table_with_old_name.sql │ │ └── ARCHIVE │ │ ├── 14_08_v1__V001_EXAMPLE_drop_table.sql │ │ └── 14_09_v1__V002_EXAMPLE_drop_column.sql │ ├── models │ ├── 14_01_v1__staging.yml │ ├── 14_02_v1__REF_POSITION_ABC_BANK.sql │ ├── 14_02_v2__REF_POSITION_ABC_BANK.sql │ ├── 14_03_v1__REF_SECURITY_INFO_ABC_BANK.sql │ ├── 14_04_v1__DIM_SECURITY.sql │ └── 14_08_v1__HIST_ABC_BANK_POSITION_WITH_CLOSING.sql │ └── snapshots │ ├── 14_05_v1__snapshots.yml │ ├── 14_06_v1__SNSH_ABC_BANK_POSITION.sql │ └── 14_07_v1__SNSH_ABC_BANK_SECURITY_INFO.sql ├── Chapter_15 └── dbt │ ├── analysis │ ├── 15_01_v1__infer_schema_snippets.sql │ ├── 15_02_v1__external_table_snippets.sql │ └── 15_15_v1__schema_evolution_snippets.sql │ └── macros │ ├── ingestion_code │ └── land_XXX │ │ ├── 15_03_v1__setup_XXX.sql │ │ ├── 15_04_v1__table_YYY.sql │ │ ├── 15_06_v1__table_ZZZ.sql │ │ └── 15_08_v1__load_XXX_landing_tables.sql │ ├── ingestion_lib │ ├── 15_05_v1__ingest_into_landing_sql.sql │ ├── 15_07_v1__ingest_semi_structured_into_landing_sql.sql │ ├── 15_09_v1__get_file_pattern.sql │ └── 15_09_v2__get_file_pattern.sql │ └── storage │ ├── 15_10_v1__save_history_with_deletion.sql │ ├── 15_11_v1__current_from_history.sql │ ├── 15_12_v1__save_history_with_deletion_from_list.sql │ ├── 15_13_v1__save_history_with_multiple_versions.sql │ └── 15_14_v1__current_from_history_with_multiple_versions.sql ├── LICENSE ├── README.md └── dbt_project_layout.png /Chapter_01/01_01_Intro_to_SQL.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Chapter 1 - Section 1: A brief introduction to SQL 3 | */ 4 | 5 | -- Example of a simple SQL query 6 | -- See 01_02_SQL_Basics.sql for commands to create the table and load sample rows 7 | SELECT ORDER_ID, CUSTOMER_CODE, TOTAL_AMOUNT 8 | FROM ORDERS 9 | WHERE YEAR(ORDER_DATE) = 2022; 10 | 11 | -------------------------------------------------------------------------------- /Chapter_01/01_02_SQL_Basics.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Chapter 1 - Section 2: SQL basics: core concepts and commands 3 | */ 4 | 5 | -- Setup a test DB and schema to create the example table storing information about orders 6 | CREATE DATABASE TEST; 7 | USE DATABASE TEST; 8 | 9 | USE SCHEMA TEST.PUBLIC; 10 | 11 | -- Example table storing information about orders 12 | CREATE TABLE ORDERS ( 13 | ORDER_ID NUMBER, 14 | CUSTOMER_CODE TEXT, 15 | TOTAL_AMOUNT FLOAT, 16 | ORDER_DATE DATE, 17 | CURRENCY TEXT DEFAULT 'EUR' 18 | ); 19 | 20 | -- Insert sample data into the table 21 | insert into ORDERS (ORDER_ID, CUSTOMER_CODE, TOTAL_AMOUNT, ORDER_DATE, CURRENCY) 22 | values (1, 'c123', 123.45, '2022-01-01', 'USD'), 23 | (2, 'C222', 222.22, '2021-12-20', 'EUR'), 24 | (3, 'C321', 321.99, '2022-01-03', 'EUR'); 25 | 26 | -- Delete all if you want to restart with new data 27 | -- DELETE FROM PUBLIC.ORDERS WHERE true; 28 | 29 | -- Example of a simple SQL query 30 | -- To create the empty table you can run the commands above 31 | SELECT ORDER_ID, CUSTOMER_CODE, TOTAL_AMOUNT 32 | FROM ORDERS 33 | WHERE YEAR(ORDER_DATE) = 2022; 34 | 35 | -- Example view built on top of the order table 36 | CREATE VIEW BIG_ORDERS AS 37 | SELECT * FROM ORDERS 38 | WHERE TOTAL_AMOUNT > 1000; 39 | 40 | -- ***** 41 | 42 | -- Creating sample db and schema 43 | CREATE DATABASE TEST; -- if not done before 44 | CREATE SCHEMA TEST.SOME_DATA; 45 | 46 | -- Sample user and role setup commands 47 | CREATE ROLE DBT_SAMPLE_ROLE; 48 | CREATE USER MY_NAME; -- Personal user 49 | CREATE USER SAMPLE_SERVICE; -- Service user 50 | GRANT ROLE DBT_SAMPLE_ROLE TO USER MY_NAME; 51 | GRANT ROLE DBT_SAMPLE_ROLE TO USER SAMPLE_SERVICE; 52 | 53 | -- Look what you have after creating the sample db, user and roles 54 | SHOW databases; 55 | SHOW warehouses; 56 | SHOW ROLES; 57 | SHOW GRANTS TO ROLE DBT_SAMPLE_ROLE; 58 | SHOW USERS; 59 | 60 | -- Cleanup the sample db, user and roles so the you can create them properly later 61 | DROP DATABASE TEST; 62 | DROP USER MY_NAME; -- or the name you used previously 63 | DROP USER SAMPLE_SERVICE; 64 | DROP ROLE DBT_SAMPLE_ROLE; 65 | 66 | 67 | -------------------------------------------------------------------------------- /Chapter_01/01_03_Setup_Snowflake.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Chapter 1 - Section 3: Set up initial users, roles and database in Snowflake 3 | */ 4 | 5 | -- Explore the default setup of your new account 6 | SHOW ROLES; 7 | SHOW GRANTS TO ROLE ; 8 | 9 | -- **Create and grant your first role 10 | USE ROLE USERADMIN; 11 | 12 | CREATE ROLE DBT_EXECUTOR_ROLE 13 | COMMENT = 'Role for the users running DBT models'; 14 | 15 | --DROP ROLE DBT_EXECUTOR_ROLE; -- if you want to drop and redo ;) 16 | 17 | GRANT ROLE DBT_EXECUTOR_ROLE TO USER ; 18 | SHOW GRANTS TO USER ; 19 | 20 | -- ** Grant the privileges to create a database 21 | USE ROLE SYSADMIN; 22 | 23 | GRANT CREATE DATABASE ON ACCOUNT TO ROLE DBT_EXECUTOR_ROLE; 24 | 25 | GRANT USAGE ON WAREHOUSE COMPUTE_WH TO ROLE DBT_EXECUTOR_ROLE; 26 | 27 | SHOW GRANTS TO ROLE DBT_EXECUTOR_ROLE; 28 | --SHOW GRANTS TO ROLE SYSADMIN; 29 | 30 | -- ** Create your first database 31 | USE ROLE DBT_EXECUTOR_ROLE; 32 | 33 | CREATE DATABASE DATA_ENG_DBT; 34 | SHOW Databases; 35 | 36 | -- configuring the default warehouse 37 | USE ROLE SYSADMIN; 38 | ALTER WAREHOUSE "COMPUTE_WH" SET 39 | WAREHOUSE_SIZE = 'XSMALL' 40 | AUTO_SUSPEND = 60 41 | AUTO_RESUME = TRUE 42 | COMMENT = 'Default Warehouse'; 43 | 44 | -- ** Create a user for the dbt application 45 | CREATE USER IF NOT EXISTS DBT_EXECUTOR 46 | COMMENT = 'User running DBT commands' 47 | PASSWORD = 'pick_a_password' 48 | DEFAULT_WAREHOUSE = 'COMPUTE_WH' 49 | DEFAULT_ROLE = 'DBT_EXECUTOR_ROLE'; 50 | 51 | -- assign the executor role to the dbt user 52 | GRANT ROLE DBT_EXECUTOR_ROLE TO USER DBT_EXECUTOR; 53 | 54 | -- Switch back to operational role we should be always working with 55 | USE ROLE DBT_EXECUTOR_ROLE; 56 | 57 | 58 | 59 | -------------------------------------------------------------------------------- /Chapter_01/01_04_Query_syntax.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Chapter 1 - Section 4: Query syntax and operators 3 | */ 4 | 5 | -- NOTE: in many queries we have added "limit 100" at the end. 6 | -- This is done to keep the result set short and the query as quick as possible 7 | -- You can comment that out or raise the number, the query will still quick, but the result set will be long. 8 | 9 | -- ** WITH clause ** 10 | -- 1. Check if we still have high priority orders pending 11 | WITH 12 | high_prio_orders as ( 13 | SELECT * 14 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 15 | WHERE O_ORDERPRIORITY IN ('1-URGENT', '2-HIGH') 16 | ) 17 | SELECT count(*) 18 | FROM high_prio_orders 19 | WHERE O_ORDERDATE < '1998-01-01' 20 | and O_ORDERSTATUS = 'O'; 21 | 22 | -- 2. Calculate some metrics for the customers in the auto industry 23 | WITH 24 | auto_customer_key as ( 25 | SELECT C_CUSTKEY 26 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" 27 | WHERE C_MKTSEGMENT = 'AUTOMOBILE' 28 | ), 29 | orders_by_auto_customer as ( 30 | SELECT O_ORDERKEY 31 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF1.ORDERS 32 | WHERE O_CUSTKEY in (SELECT * FROM auto_customer_key) 33 | ), 34 | metrics as ( 35 | SELECT 'customers' as metric, count(*) as value 36 | FROM auto_customer_key 37 | 38 | UNION ALL 39 | 40 | SELECT 'orders by these customers', count(*) 41 | FROM orders_by_auto_customer 42 | ) 43 | SELECT * FROM metrics; 44 | 45 | -- ** SELECT clause ** 46 | -- Sample SELECT with alias 47 | SELECT 48 | O_ORDERKEY, 49 | ord.O_CUSTKEY, 50 | cust.C_NAME as CUSTOMER_NAME 51 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF1.ORDERS as ord 52 | JOIN SNOWFLAKE_SAMPLE_DATA.TPCH_SF1.CUSTOMER as cust 53 | ON cust.C_CUSTKEY = ord.O_CUSTKEY 54 | limit 100; 55 | 56 | -- Sample SELECT with column numbers 57 | SELECT $1 as ORDER_KEY, $2 as CUST_KEY 58 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF1.ORDERS 59 | limit 100; 60 | 61 | -- Sample select with expressions 62 | SELECT 63 | P_PARTKEY 64 | , UPPER(P_NAME) as P_NAME 65 | , P_RETAILPRICE 66 | , P_RETAILPRICE * 0.9 as P_DISCOUNTED_PRICE 67 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."PART" 68 | limit 100; 69 | 70 | -- ** FROM clause ** 71 | -- no FROM clause 72 | SELECT 1 + 1 as sum, current_date as today; 73 | 74 | -- FROM VALUES, aka inline table 75 | SELECT * FROM ( 76 | VALUES ('IT', 'ITA', 'Italy') 77 | ,('US', 'USA', 'United States of America') 78 | ,('SF', 'FIN', 'Finland (Suomi)') 79 | as inline_table (code_2, code_3, country_name) 80 | ); 81 | 82 | -- SELECT from multiple tables 83 | SELECT count(*) 84 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."LINEITEM" as l 85 | ,"SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" as o 86 | ,"SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" as c 87 | ,"SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."PART" as p 88 | WHERE o.O_ORDERKEY = l.L_ORDERKEY 89 | and c.C_CUSTKEY = o.O_CUSTKEY 90 | and p.P_PARTKEY = l.L_PARTKEY 91 | ; 92 | 93 | -- ** WHERE clause 94 | -- Example of a Predicate 95 | SELECT O_ORDERKEY, O_CUSTKEY, O_TOTALPRICE 96 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 97 | WHERE O_TOTALPRICE > 500000 98 | limit 100; 99 | 100 | -- WHERE false example 101 | SELECT O_ORDERKEY,O_CUSTKEY, 1 as an_int, null::number as a_num 102 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 103 | WHERE false; 104 | 105 | -- ** GROUP BY clause 106 | -- group by column name 107 | SELECT O_CUSTKEY, sum(O_TOTALPRICE) 108 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 109 | GROUP BY O_CUSTKEY; 110 | 111 | -- group by column number 112 | SELECT O_CUSTKEY, sum(O_TOTALPRICE) 113 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 114 | GROUP BY 1; 115 | 116 | -- group by SQL expression 117 | SELECT YEAR(O_ORDERDATE), sum(O_TOTALPRICE) 118 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 119 | GROUP BY YEAR(O_ORDERDATE) 120 | ORDER BY YEAR(O_ORDERDATE); 121 | 122 | -- group by more than one expression 123 | SELECT YEAR(O_ORDERDATE),MONTH(O_ORDERDATE),sum(O_TOTALPRICE) 124 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 125 | GROUP BY YEAR(O_ORDERDATE), MONTH(O_ORDERDATE) 126 | ORDER BY YEAR(O_ORDERDATE), MONTH(O_ORDERDATE); 127 | 128 | -- ** HAVING clause 129 | -- filtering on the count of rows by group 130 | SELECT YEAR(O_ORDERDATE), MONTH(O_ORDERDATE), sum(O_TOTALPRICE) 131 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 132 | GROUP BY YEAR(O_ORDERDATE), MONTH(O_ORDERDATE) 133 | HAVING count(*) < 10000 134 | ORDER BY YEAR(O_ORDERDATE), MONTH(O_ORDERDATE); 135 | 136 | -- ** QUALIFY clause 137 | -- Keep only the most recent row per order and line 138 | SELECT * 139 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."LINEITEM" 140 | QUALIFY row_number() over( 141 | partition by L_ORDERKEY, L_LINENUMBER 142 | order by L_COMMITDATE desc ) = 1 143 | limit 100; 144 | 145 | -- Select the GOOD months, with sales above the yearly average 146 | WITH 147 | monthly_totals as ( 148 | SELECT 149 | YEAR(O_ORDERDATE) as year, 150 | MONTH(O_ORDERDATE) as month, 151 | sum(O_TOTALPRICE) as month_tot 152 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 153 | GROUP BY YEAR(O_ORDERDATE), MONTH(O_ORDERDATE) 154 | ) 155 | SELECT year, month, month_tot 156 | ,avg(month_tot) over(partition by YEAR) as year_avg 157 | FROM monthly_totals 158 | QUALIFY month_tot > year_avg 159 | ORDER BY YEAR, MONTH; 160 | 161 | -- ** SQL Operators 162 | -- Arithmetic operators 163 | SELECT 1 + '2' as three, (3+2) * 4 as twenty 164 | WHERE twenty % 2 = 0; 165 | 166 | -- Comparison operators 167 | SELECT 2 < 1 as nope, '3' != 'three' as yep 168 | WHERE 1 != 2; 169 | 170 | -- Logical operators 171 | SELECT *, 172 | (C_ACCTBAL > 7500) AND (C_NATIONKEY = 24) as IS_TOP_US_CUST 173 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" 174 | WHERE (C_NAME IS NOT null) AND IS_TOP_US_CUST 175 | limit 100; 176 | 177 | -- Set Operators 178 | SELECT C_NAME, C_ADDRESS, C_PHONE 179 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" 180 | WHERE C_NATIONKEY IN (8, 24) 181 | 182 | UNION 183 | 184 | SELECT C_NAME, C_ADDRESS, C_PHONE 185 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" 186 | WHERE C_MKTSEGMENT = 'AUTOMOBILE' 187 | ; 188 | 189 | -- Subquery operators 190 | SELECT C_NAME, C_ADDRESS, C_PHONE 191 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" 192 | WHERE C_NATIONKEY = ( 193 | SELECT N_NATIONKEY 194 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."NATION" 195 | WHERE N_NAME = 'JAPAN' 196 | ) 197 | limit 100; 198 | 199 | -- Same query with IN operator 200 | SELECT C_NAME, C_ADDRESS, C_PHONE 201 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" 202 | WHERE C_NATIONKEY IN ( 203 | SELECT N_NATIONKEY 204 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."NATION" 205 | WHERE N_NAME IN ('JAPAN', 'CANADA') 206 | ); 207 | 208 | 209 | -------------------------------------------------------------------------------- /Chapter_01/01_05_JOIN_clause.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Chapter 1 - Section 5: SQL JOIN – how to put different data together 3 | */ 4 | 5 | -- ** SET UP the Orders and Customers tables 6 | USE SCHEMA PUBLIC; 7 | 8 | -- Example table storing information about orders 9 | CREATE TABLE WEB_ORDER ( 10 | ORDER_ID NUMBER, 11 | ORDER_PLACED_BY TEXT, 12 | ORDER_VALUE FLOAT 13 | ); 14 | 15 | -- Insert sample data into the table 16 | insert into WEB_ORDER (ORDER_ID, ORDER_PLACED_BY, ORDER_VALUE) 17 | values (1, '123', 123.45), 18 | (2, 'C222', 222.22), 19 | (3, '321', 321.99); 20 | 21 | -- Create the customer table 22 | CREATE TABLE CUSTOMER ( 23 | CUSTOMER_ID TEXT, 24 | CUSTOMER_NAME TEXT, 25 | ADDRESS TEXT 26 | ); 27 | 28 | -- Insert sample data in the customer table 29 | insert into CUSTOMER (CUSTOMER_ID, CUSTOMER_NAME, ADDRESS) 30 | values 31 | ('123', 'Big Buyer LLP', 'Nice place road, 00100 SOMEWHERE'), 32 | ('C222', 'Some customer', 'A place') 33 | ; 34 | 35 | -- Insert "duplicated" customers with the same 123 code 36 | insert into CUSTOMER (CUSTOMER_ID, CUSTOMER_NAME, ADDRESS) 37 | values 38 | ('123', 'Another Customer', 'Some road, 10250 SOME PLACE'), 39 | ('123', 'A third customer', 'No way road, 20100 NOWHERE') 40 | ; 41 | 42 | --DELETE FROM CUSTOMER where true; 43 | 44 | -- ** Try out the join between the two tables with different data in them 45 | SELECT * 46 | FROM web_order 47 | JOIN customer ON ORDER_PLACED_BY = CUSTOMER_ID; 48 | 49 | -- ** Visual representation of JOIN results using sets 50 | SELECT * 51 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 52 | LEFT OUTER JOIN "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."CUSTOMER" 53 | ON C_CUSTKEY = O_CUSTKEY 54 | WHERE C_CUSTKEY is NULL; 55 | -------------------------------------------------------------------------------- /Chapter_01/01_06_Window_functions.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Chapter 1 - Section 6: Advanced: window function introduction 3 | */ 4 | 5 | -- Calculating daily or monthly measures with window functions 6 | SELECT 7 | O_ORDERKEY, 8 | O_CUSTKEY, 9 | O_ORDERDATE, 10 | O_TOTALPRICE, 11 | avg(O_TOTALPRICE) over(partition by O_ORDERDATE) as daily_avg, 12 | sum(O_TOTALPRICE) over(partition by O_ORDERDATE) as daily_total, 13 | sum(O_TOTALPRICE) over(partition by 14 | DATE_TRUNC(MONTH, O_ORDERDATE)) as monthly_total, 15 | O_TOTALPRICE / daily_avg * 100 as avg_pct, 16 | O_TOTALPRICE / daily_total * 100 as day_pct, 17 | O_TOTALPRICE / monthly_total * 100 as month_pct 18 | FROM "SNOWFLAKE_SAMPLE_DATA"."TPCH_SF1"."ORDERS" 19 | QUALIFY row_number() over(partition by O_ORDERDATE 20 | order by O_TOTALPRICE DESC) <= 5 21 | order by O_ORDERDATE, O_TOTALPRICE desc; 22 | 23 | 24 | 25 | -------------------------------------------------------------------------------- /Chapter_03/03_04_Use_cases.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Chapter 3 - Section 4: MODELING USE CASES AND PATTERNS 3 | */ 4 | 5 | -- Use the correct role 6 | USE ROLE DBT_EXECUTOR_ROLE; 7 | 8 | -- Creating a sample Entity table with a recursive relationship 9 | CREATE OR REPLACE TABLE DATA_ENG_DBT.PUBLIC.Entity as 10 | SELECT * FROM ( VALUES 11 | (1, null::Number, 'President'), 12 | (2,1,'VP Sales'), 13 | (3,1,'VP Tech'), 14 | (4,2,'Sales Dir'), 15 | (5,3,'Lead Architect'), 16 | (6,3,'Software Dev Manager'), 17 | (7,6,'Proj Mgr'), 18 | (8,6,'Software Eng') 19 | ) as v (Entity_KEY, Parent_KEY, Entity_Name); 20 | 21 | -- Using a recursive CTE to query the recursive relationship in the Entity table 22 | WITH recursive 23 | ENTITY_HIERARCHY as ( 24 | SELECT 25 | Entity_KEY 26 | , Parent_KEY 27 | , Entity_Name 28 | , 1 as level 29 | , '-' as parent_name 30 | , Entity_KEY::string as key_path 31 | , Entity_Name::string as name_path 32 | FROM DATA_ENG_DBT.PUBLIC.Entity 33 | WHERE Parent_KEY is null 34 | 35 | UNION ALL 36 | 37 | SELECT 38 | ENT.Entity_KEY 39 | , ENT.Parent_KEY 40 | , ENT.Entity_Name 41 | , HIER.level + 1 as level 42 | , HIER.Entity_Name as parent_name 43 | , HIER.key_path || '-' || ENT.Entity_KEY::string as key_path 44 | , HIER.name_path || '-' || ENT.Entity_Name::string as name_path 45 | FROM DATA_ENG_DBT.PUBLIC.Entity as ENT 46 | JOIN ENTITY_HIERARCHY as HIER ON HIER.Entity_KEY = ENT.Parent_KEY 47 | ) 48 | SELECT * FROM ENTITY_HIERARCHY; -------------------------------------------------------------------------------- /Chapter_05/README.md: -------------------------------------------------------------------------------- 1 | # Chapter 5 materials 2 | The materials for the chapter are organised in the following folders: 3 | 4 | * **data**: the folder contains sample data provided with the project. 5 | 6 | * **dbt**: the folder contains source code and configurations for dbt. 7 | Multiple versions of the same source file might be provided to track 8 | the evolution of the file along the chapter. 9 | 10 | * **snowflake**: the folder contains SQL scripts to be used in Snowflake, 11 | generally run from a Snowflake worksheet. 12 | 13 | -------------------------------------------------------------------------------- /Chapter_05/data/ABC_Bank_PORTFOLIO__2021-04-09.csv: -------------------------------------------------------------------------------- 1 | accountID,symbol,description,exchange,report_date,quantity,cost_base,position_value,currency 2 | ABC000123,GCM,GRAN COLOMBIA GOLD CORP,TSE,4/9/21,100,559,678,CAD 3 | ABC000123,TTD,TRADE DESK INC/THE -CLASS A,NASDAQ,4/9/21,10,5310.45,6925.6,USD 4 | ABC000123,STAR,ISTAR INC,NYSE,4/9/21,150,2444,2725.5,USD -------------------------------------------------------------------------------- /Chapter_05/dbt/05_03_v1__source_abc_bank.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | sources: 4 | 5 | - name: abc_bank 6 | 7 | database: PORTFOLIO_TRACKING 8 | schema: SOURCE_DATA 9 | 10 | tables: 11 | - name: ABC_BANK_POSITION 12 | -------------------------------------------------------------------------------- /Chapter_05/dbt/05_03_v2__source_abc_bank.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | sources: 4 | 5 | - name: abc_bank 6 | 7 | database: PORTFOLIO_TRACKING 8 | schema: SOURCE_DATA 9 | 10 | tables: 11 | - name: ABC_BANK_POSITION 12 | description: The landing table holding the data imported from the CSV extracted by ABC Bank. 13 | columns: 14 | - name: ACCOUNTID 15 | description: The code for the account at the ABC Bank. 16 | tests: 17 | - not_null 18 | - name: SYMBOL 19 | description: The symbol of the security for the ABC Bank. 20 | tests: 21 | - unique 22 | - not_null 23 | - name: DESCRIPTION 24 | description: The name of the security at the ABC Bank. 25 | tests: 26 | - not_null 27 | - name: EXCHANGE 28 | description: The short name or code of the exchange where the security is traded. 29 | tests: 30 | - not_null 31 | - name: REPORT_DATE 32 | description: > 33 | The date of the portfolio report extracted by ABC Bank. 34 | We consider this position to be the effective from this date forward, until a change is seen. 35 | tests: 36 | - not_null 37 | - name: QUANTITY 38 | description: The number of secuities we hold in the portfolio at ABC Bank at the Report Date. 39 | tests: 40 | - not_null 41 | - name: COST_BASE 42 | description: The cost we paid attributable to the secuities we hold in the portfolio at ABC Bank at the Report Date. 43 | tests: 44 | - not_null 45 | - name: POSITION_VALUE 46 | description: The value of the secuities we hold in the portfolio at ABC Bank acording to market quotation on the Report Date. 47 | tests: 48 | - not_null 49 | - name: CURRENCY 50 | description: The currency for the monetary amounts of the position. 51 | tests: 52 | - not_null 53 | -------------------------------------------------------------------------------- /Chapter_05/dbt/05_04_v1__POSITION_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | * 3 | , POSITION_VALUE - COST_BASE as UNREALIZED_PROFIT 4 | , ROUND(UNREALIZED_PROFIT / COST_BASE, 5)*100 as UNREALIZED_PROFIT_PCT 5 | FROM {{ source('abc_bank', 'ABC_BANK_POSITION') }} 6 | -------------------------------------------------------------------------------- /Chapter_05/dbt/05_05_v1__dbt_project.yml: -------------------------------------------------------------------------------- 1 | 2 | # Name your project! Project 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: 'portfolio_tracking' 6 | version: '1.0.0' 7 | config-version: 2 8 | 9 | # This setting configures which "profile" dbt uses for this project. 10 | profile: 'default' 11 | 12 | # These configurations specify where dbt should look for different types of files. 13 | # The `source-paths` config, for example, states that models in this project can be 14 | # found in the "models/" directory. You probably won't need to change these! 15 | model-paths: ["models"] 16 | analysis-paths: ["analyses"] 17 | test-paths: ["tests"] 18 | seed-paths: ["seeds"] 19 | macro-paths: ["macros"] 20 | snapshot-paths: ["snapshots"] 21 | 22 | target-path: "target" # directory which will store compiled SQL files 23 | clean-targets: # directories to be removed by `dbt clean` 24 | - "target" 25 | - "dbt_packages" 26 | 27 | 28 | # Configuring models 29 | # Full documentation: https://docs.getdbt.com/docs/configuring-models 30 | 31 | # In this example config, we tell dbt to build all models in the example/ directory 32 | # as tables. These settings can be overridden in the individual model files 33 | # using the `{{ config(...) }}` macro. 34 | models: 35 | portfolio_tracking: 36 | +materialized: view 37 | 38 | refined: # Applies to all files under models/refined/ 39 | +materialized: table 40 | +schema: REFINED 41 | -------------------------------------------------------------------------------- /Chapter_05/snowflake/05_01_Setup_Portfolio_tracking_project.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Steps to setup the PRoject tracking project in Snowflake 3 | */ 4 | 5 | -- ** 1 - Create the DB (as the DBT_EXECUTOR_ROLE) ** 6 | USE ROLE DBT_EXECUTOR_ROLE; 7 | 8 | CREATE DATABASE PORTFOLIO_TRACKING 9 | COMMENT = 'DB for the portfolio tracking project managed with dbt'; 10 | 11 | -- From initial setup 12 | -- GRANT USAGE ON WAREHOUSE COMPUTE_WH TO ROLE DBT_EXECUTOR_ROLE; 13 | 14 | -- ** 2 - Drop dbt default project after initial test 15 | DROP SCHEMA "PORTFOLIO_TRACKING"."RZ"; 16 | 17 | -- ** 3 - Create a user for the PROD environment, 18 | -- if you want it different from the one we already set-up before 19 | USE ROLE USERADMIN; 20 | CREATE USER IF NOT EXISTS DBT_PROD_USER 21 | COMMENT = 'User running DBT commands in PROD env' 22 | PASSWORD = 'pick_a_password' 23 | DEFAULT_WAREHOUSE = 'COMPUTE_WH' 24 | DEFAULT_ROLE = 'DBT_EXECUTOR_ROLE' 25 | ; 26 | 27 | GRANT ROLE DBT_EXECUTOR_ROLE TO USER DBT_PROD_USER; 28 | 29 | USE ROLE DBT_EXECUTOR_ROLE; -------------------------------------------------------------------------------- /Chapter_05/snowflake/05_02_Setup_ABC_Bank_Landing_table.sql: -------------------------------------------------------------------------------- 1 | USE ROLE DBT_EXECUTOR_ROLE; 2 | 3 | -- ** 1 ** Create the schema for the source data 4 | CREATE SCHEMA PORTFOLIO_TRACKING.SOURCE_DATA; 5 | 6 | -- ** 2 ** Create the landing table for ABC_BANK data 7 | CREATE OR REPLACE TABLE PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION ( 8 | accountID TEXT, 9 | symbol TEXT, 10 | description TEXT, 11 | exchange TEXT, 12 | report_date DATE, 13 | quantity NUMBER(38,0), 14 | cost_base NUMBER(38,5), 15 | position_value NUMBER(38,5), 16 | currency TEXT 17 | ); 18 | 19 | -- ** 3 ** Create the file format to load the data for ABC_BANK 20 | CREATE FILE FORMAT "PORTFOLIO_TRACKING"."SOURCE_DATA".ABC_BANK_CSV_FILE_FORMAT 21 | TYPE = 'CSV' 22 | COMPRESSION = 'AUTO' 23 | FIELD_DELIMITER = ',' 24 | RECORD_DELIMITER = '\n' 25 | SKIP_HEADER = 1 26 | FIELD_OPTIONALLY_ENCLOSED_BY = '\042' 27 | TRIM_SPACE = FALSE 28 | ERROR_ON_COLUMN_COUNT_MISMATCH = TRUE 29 | ESCAPE = 'NONE' 30 | ESCAPE_UNENCLOSED_FIELD = '\134' 31 | DATE_FORMAT = 'AUTO' 32 | TIMESTAMP_FORMAT = 'AUTO' 33 | NULL_IF = ('\\N') 34 | ; 35 | 36 | /* ** how to load a file in a stage and from the stage in the landing table 37 | ** if you have SnowSql installed 38 | 39 | USE ROLE DBT_EXECUTOR_ROLE; 40 | 41 | CREATE STAGE "PORTFOLIO_TRACKING"."PUBLIC".ABC_BANK COMMENT = 'ABC Bank files'; 42 | 43 | PUT file://ABC_Bank_PORTFOLIO.csv 44 | @ABC_BANK 45 | ; 46 | 47 | COPY INTO "PORTFOLIO_TRACKING"."SOURCE_DATA"."ABC_BANK_POSITION" 48 | FROM @ABC_BANK 49 | FILE_FORMAT = '"PORTFOLIO_TRACKING"."SOURCE_DATA"."ABC_BANK_CSV_FILE_FORMAT"' 50 | ON_ERROR = 'ABORT_STATEMENT' 51 | PURGE = TRUE; 52 | */ 53 | -------------------------------------------------------------------------------- /Chapter_06/csv/country_ISO_3166.csv: -------------------------------------------------------------------------------- 1 | country_name,country_code_2_letter,country_code_3_letter,country_code_numeric,iso_3166_2,region,sub_region,intermediate_region,region_code,sub_region_code,intermediate_region_code 2 | Afghanistan,AF,AFG,4,ISO 3166-2:AF,Asia,Southern Asia,,142,34, 3 | Åland Islands,AX,ALA,248,ISO 3166-2:AX,Europe,Northern Europe,,150,154, 4 | Albania,AL,ALB,8,ISO 3166-2:AL,Europe,Southern Europe,,150,39, 5 | Algeria,DZ,DZA,12,ISO 3166-2:DZ,Africa,Northern Africa,,2,15, 6 | American Samoa,AS,ASM,16,ISO 3166-2:AS,Oceania,Polynesia,,9,61, 7 | Andorra,AD,AND,20,ISO 3166-2:AD,Europe,Southern Europe,,150,39, 8 | Angola,AO,AGO,24,ISO 3166-2:AO,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 9 | Anguilla,AI,AIA,660,ISO 3166-2:AI,Americas,Latin America and the Caribbean,Caribbean,19,419,29 10 | Antarctica,AQ,ATA,10,ISO 3166-2:AQ,,,,,, 11 | Antigua and Barbuda,AG,ATG,28,ISO 3166-2:AG,Americas,Latin America and the Caribbean,Caribbean,19,419,29 12 | Argentina,AR,ARG,32,ISO 3166-2:AR,Americas,Latin America and the Caribbean,South America,19,419,5 13 | Armenia,AM,ARM,51,ISO 3166-2:AM,Asia,Western Asia,,142,145, 14 | Aruba,AW,ABW,533,ISO 3166-2:AW,Americas,Latin America and the Caribbean,Caribbean,19,419,29 15 | Australia,AU,AUS,36,ISO 3166-2:AU,Oceania,Australia and New Zealand,,9,53, 16 | Austria,AT,AUT,40,ISO 3166-2:AT,Europe,Western Europe,,150,155, 17 | Azerbaijan,AZ,AZE,31,ISO 3166-2:AZ,Asia,Western Asia,,142,145, 18 | Bahamas,BS,BHS,44,ISO 3166-2:BS,Americas,Latin America and the Caribbean,Caribbean,19,419,29 19 | Bahrain,BH,BHR,48,ISO 3166-2:BH,Asia,Western Asia,,142,145, 20 | Bangladesh,BD,BGD,50,ISO 3166-2:BD,Asia,Southern Asia,,142,34, 21 | Barbados,BB,BRB,52,ISO 3166-2:BB,Americas,Latin America and the Caribbean,Caribbean,19,419,29 22 | Belarus,BY,BLR,112,ISO 3166-2:BY,Europe,Eastern Europe,,150,151, 23 | Belgium,BE,BEL,56,ISO 3166-2:BE,Europe,Western Europe,,150,155, 24 | Belize,BZ,BLZ,84,ISO 3166-2:BZ,Americas,Latin America and the Caribbean,Central America,19,419,13 25 | Benin,BJ,BEN,204,ISO 3166-2:BJ,Africa,Sub-Saharan Africa,Western Africa,2,202,11 26 | Bermuda,BM,BMU,60,ISO 3166-2:BM,Americas,Northern America,,19,21, 27 | Bhutan,BT,BTN,64,ISO 3166-2:BT,Asia,Southern Asia,,142,34, 28 | Bolivia (Plurinational State of),BO,BOL,68,ISO 3166-2:BO,Americas,Latin America and the Caribbean,South America,19,419,5 29 | "Bonaire, Sint Eustatius and Saba",BQ,BES,535,ISO 3166-2:BQ,Americas,Latin America and the Caribbean,Caribbean,19,419,29 30 | Bosnia and Herzegovina,BA,BIH,70,ISO 3166-2:BA,Europe,Southern Europe,,150,39, 31 | Botswana,BW,BWA,72,ISO 3166-2:BW,Africa,Sub-Saharan Africa,Southern Africa,2,202,18 32 | Bouvet Island,BV,BVT,74,ISO 3166-2:BV,Americas,Latin America and the Caribbean,South America,19,419,5 33 | Brazil,BR,BRA,76,ISO 3166-2:BR,Americas,Latin America and the Caribbean,South America,19,419,5 34 | British Indian Ocean Territory,IO,IOT,86,ISO 3166-2:IO,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 35 | Brunei Darussalam,BN,BRN,96,ISO 3166-2:BN,Asia,South-eastern Asia,,142,35, 36 | Bulgaria,BG,BGR,100,ISO 3166-2:BG,Europe,Eastern Europe,,150,151, 37 | Burkina Faso,BF,BFA,854,ISO 3166-2:BF,Africa,Sub-Saharan Africa,Western Africa,2,202,11 38 | Burundi,BI,BDI,108,ISO 3166-2:BI,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 39 | Cabo Verde,CV,CPV,132,ISO 3166-2:CV,Africa,Sub-Saharan Africa,Western Africa,2,202,11 40 | Cambodia,KH,KHM,116,ISO 3166-2:KH,Asia,South-eastern Asia,,142,35, 41 | Cameroon,CM,CMR,120,ISO 3166-2:CM,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 42 | Canada,CA,CAN,124,ISO 3166-2:CA,Americas,Northern America,,19,21, 43 | Cayman Islands,KY,CYM,136,ISO 3166-2:KY,Americas,Latin America and the Caribbean,Caribbean,19,419,29 44 | Central African Republic,CF,CAF,140,ISO 3166-2:CF,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 45 | Chad,TD,TCD,148,ISO 3166-2:TD,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 46 | Chile,CL,CHL,152,ISO 3166-2:CL,Americas,Latin America and the Caribbean,South America,19,419,5 47 | China,CN,CHN,156,ISO 3166-2:CN,Asia,Eastern Asia,,142,30, 48 | Christmas Island,CX,CXR,162,ISO 3166-2:CX,Oceania,Australia and New Zealand,,9,53, 49 | Cocos (Keeling) Islands,CC,CCK,166,ISO 3166-2:CC,Oceania,Australia and New Zealand,,9,53, 50 | Colombia,CO,COL,170,ISO 3166-2:CO,Americas,Latin America and the Caribbean,South America,19,419,5 51 | Comoros,KM,COM,174,ISO 3166-2:KM,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 52 | Congo,CG,COG,178,ISO 3166-2:CG,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 53 | "Congo, Democratic Republic of the",CD,COD,180,ISO 3166-2:CD,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 54 | Cook Islands,CK,COK,184,ISO 3166-2:CK,Oceania,Polynesia,,9,61, 55 | Costa Rica,CR,CRI,188,ISO 3166-2:CR,Americas,Latin America and the Caribbean,Central America,19,419,13 56 | Côte d'Ivoire,CI,CIV,384,ISO 3166-2:CI,Africa,Sub-Saharan Africa,Western Africa,2,202,11 57 | Croatia,HR,HRV,191,ISO 3166-2:HR,Europe,Southern Europe,,150,39, 58 | Cuba,CU,CUB,192,ISO 3166-2:CU,Americas,Latin America and the Caribbean,Caribbean,19,419,29 59 | Curaçao,CW,CUW,531,ISO 3166-2:CW,Americas,Latin America and the Caribbean,Caribbean,19,419,29 60 | Cyprus,CY,CYP,196,ISO 3166-2:CY,Asia,Western Asia,,142,145, 61 | Czechia,CZ,CZE,203,ISO 3166-2:CZ,Europe,Eastern Europe,,150,151, 62 | Denmark,DK,DNK,208,ISO 3166-2:DK,Europe,Northern Europe,,150,154, 63 | Djibouti,DJ,DJI,262,ISO 3166-2:DJ,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 64 | Dominica,DM,DMA,212,ISO 3166-2:DM,Americas,Latin America and the Caribbean,Caribbean,19,419,29 65 | Dominican Republic,DO,DOM,214,ISO 3166-2:DO,Americas,Latin America and the Caribbean,Caribbean,19,419,29 66 | Ecuador,EC,ECU,218,ISO 3166-2:EC,Americas,Latin America and the Caribbean,South America,19,419,5 67 | Egypt,EG,EGY,818,ISO 3166-2:EG,Africa,Northern Africa,,2,15, 68 | El Salvador,SV,SLV,222,ISO 3166-2:SV,Americas,Latin America and the Caribbean,Central America,19,419,13 69 | Equatorial Guinea,GQ,GNQ,226,ISO 3166-2:GQ,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 70 | Eritrea,ER,ERI,232,ISO 3166-2:ER,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 71 | Estonia,EE,EST,233,ISO 3166-2:EE,Europe,Northern Europe,,150,154, 72 | Eswatini,SZ,SWZ,748,ISO 3166-2:SZ,Africa,Sub-Saharan Africa,Southern Africa,2,202,18 73 | Ethiopia,ET,ETH,231,ISO 3166-2:ET,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 74 | Falkland Islands (Malvinas),FK,FLK,238,ISO 3166-2:FK,Americas,Latin America and the Caribbean,South America,19,419,5 75 | Faroe Islands,FO,FRO,234,ISO 3166-2:FO,Europe,Northern Europe,,150,154, 76 | Fiji,FJ,FJI,242,ISO 3166-2:FJ,Oceania,Melanesia,,9,54, 77 | Finland,FI,FIN,246,ISO 3166-2:FI,Europe,Northern Europe,,150,154, 78 | France,FR,FRA,250,ISO 3166-2:FR,Europe,Western Europe,,150,155, 79 | French Guiana,GF,GUF,254,ISO 3166-2:GF,Americas,Latin America and the Caribbean,South America,19,419,5 80 | French Polynesia,PF,PYF,258,ISO 3166-2:PF,Oceania,Polynesia,,9,61, 81 | French Southern Territories,TF,ATF,260,ISO 3166-2:TF,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 82 | Gabon,GA,GAB,266,ISO 3166-2:GA,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 83 | Gambia,GM,GMB,270,ISO 3166-2:GM,Africa,Sub-Saharan Africa,Western Africa,2,202,11 84 | Georgia,GE,GEO,268,ISO 3166-2:GE,Asia,Western Asia,,142,145, 85 | Germany,DE,DEU,276,ISO 3166-2:DE,Europe,Western Europe,,150,155, 86 | Ghana,GH,GHA,288,ISO 3166-2:GH,Africa,Sub-Saharan Africa,Western Africa,2,202,11 87 | Gibraltar,GI,GIB,292,ISO 3166-2:GI,Europe,Southern Europe,,150,39, 88 | Greece,GR,GRC,300,ISO 3166-2:GR,Europe,Southern Europe,,150,39, 89 | Greenland,GL,GRL,304,ISO 3166-2:GL,Americas,Northern America,,19,21, 90 | Grenada,GD,GRD,308,ISO 3166-2:GD,Americas,Latin America and the Caribbean,Caribbean,19,419,29 91 | Guadeloupe,GP,GLP,312,ISO 3166-2:GP,Americas,Latin America and the Caribbean,Caribbean,19,419,29 92 | Guam,GU,GUM,316,ISO 3166-2:GU,Oceania,Micronesia,,9,57, 93 | Guatemala,GT,GTM,320,ISO 3166-2:GT,Americas,Latin America and the Caribbean,Central America,19,419,13 94 | Guernsey,GG,GGY,831,ISO 3166-2:GG,Europe,Northern Europe,Channel Islands,150,154,830 95 | Guinea,GN,GIN,324,ISO 3166-2:GN,Africa,Sub-Saharan Africa,Western Africa,2,202,11 96 | Guinea-Bissau,GW,GNB,624,ISO 3166-2:GW,Africa,Sub-Saharan Africa,Western Africa,2,202,11 97 | Guyana,GY,GUY,328,ISO 3166-2:GY,Americas,Latin America and the Caribbean,South America,19,419,5 98 | Haiti,HT,HTI,332,ISO 3166-2:HT,Americas,Latin America and the Caribbean,Caribbean,19,419,29 99 | Heard Island and McDonald Islands,HM,HMD,334,ISO 3166-2:HM,Oceania,Australia and New Zealand,,9,53, 100 | Holy See,VA,VAT,336,ISO 3166-2:VA,Europe,Southern Europe,,150,39, 101 | Honduras,HN,HND,340,ISO 3166-2:HN,Americas,Latin America and the Caribbean,Central America,19,419,13 102 | Hong Kong,HK,HKG,344,ISO 3166-2:HK,Asia,Eastern Asia,,142,30, 103 | Hungary,HU,HUN,348,ISO 3166-2:HU,Europe,Eastern Europe,,150,151, 104 | Iceland,IS,ISL,352,ISO 3166-2:IS,Europe,Northern Europe,,150,154, 105 | India,IN,IND,356,ISO 3166-2:IN,Asia,Southern Asia,,142,34, 106 | Indonesia,ID,IDN,360,ISO 3166-2:ID,Asia,South-eastern Asia,,142,35, 107 | Iran (Islamic Republic of),IR,IRN,364,ISO 3166-2:IR,Asia,Southern Asia,,142,34, 108 | Iraq,IQ,IRQ,368,ISO 3166-2:IQ,Asia,Western Asia,,142,145, 109 | Ireland,IE,IRL,372,ISO 3166-2:IE,Europe,Northern Europe,,150,154, 110 | Isle of Man,IM,IMN,833,ISO 3166-2:IM,Europe,Northern Europe,,150,154, 111 | Israel,IL,ISR,376,ISO 3166-2:IL,Asia,Western Asia,,142,145, 112 | Italy,IT,ITA,380,ISO 3166-2:IT,Europe,Southern Europe,,150,39, 113 | Jamaica,JM,JAM,388,ISO 3166-2:JM,Americas,Latin America and the Caribbean,Caribbean,19,419,29 114 | Japan,JP,JPN,392,ISO 3166-2:JP,Asia,Eastern Asia,,142,30, 115 | Jersey,JE,JEY,832,ISO 3166-2:JE,Europe,Northern Europe,Channel Islands,150,154,830 116 | Jordan,JO,JOR,400,ISO 3166-2:JO,Asia,Western Asia,,142,145, 117 | Kazakhstan,KZ,KAZ,398,ISO 3166-2:KZ,Asia,Central Asia,,142,143, 118 | Kenya,KE,KEN,404,ISO 3166-2:KE,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 119 | Kiribati,KI,KIR,296,ISO 3166-2:KI,Oceania,Micronesia,,9,57, 120 | Korea (Democratic People's Republic of),KP,PRK,408,ISO 3166-2:KP,Asia,Eastern Asia,,142,30, 121 | "Korea, Republic of",KR,KOR,410,ISO 3166-2:KR,Asia,Eastern Asia,,142,30, 122 | Kuwait,KW,KWT,414,ISO 3166-2:KW,Asia,Western Asia,,142,145, 123 | Kyrgyzstan,KG,KGZ,417,ISO 3166-2:KG,Asia,Central Asia,,142,143, 124 | Lao People's Democratic Republic,LA,LAO,418,ISO 3166-2:LA,Asia,South-eastern Asia,,142,35, 125 | Latvia,LV,LVA,428,ISO 3166-2:LV,Europe,Northern Europe,,150,154, 126 | Lebanon,LB,LBN,422,ISO 3166-2:LB,Asia,Western Asia,,142,145, 127 | Lesotho,LS,LSO,426,ISO 3166-2:LS,Africa,Sub-Saharan Africa,Southern Africa,2,202,18 128 | Liberia,LR,LBR,430,ISO 3166-2:LR,Africa,Sub-Saharan Africa,Western Africa,2,202,11 129 | Libya,LY,LBY,434,ISO 3166-2:LY,Africa,Northern Africa,,2,15, 130 | Liechtenstein,LI,LIE,438,ISO 3166-2:LI,Europe,Western Europe,,150,155, 131 | Lithuania,LT,LTU,440,ISO 3166-2:LT,Europe,Northern Europe,,150,154, 132 | Luxembourg,LU,LUX,442,ISO 3166-2:LU,Europe,Western Europe,,150,155, 133 | Macao,MO,MAC,446,ISO 3166-2:MO,Asia,Eastern Asia,,142,30, 134 | Madagascar,MG,MDG,450,ISO 3166-2:MG,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 135 | Malawi,MW,MWI,454,ISO 3166-2:MW,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 136 | Malaysia,MY,MYS,458,ISO 3166-2:MY,Asia,South-eastern Asia,,142,35, 137 | Maldives,MV,MDV,462,ISO 3166-2:MV,Asia,Southern Asia,,142,34, 138 | Mali,ML,MLI,466,ISO 3166-2:ML,Africa,Sub-Saharan Africa,Western Africa,2,202,11 139 | Malta,MT,MLT,470,ISO 3166-2:MT,Europe,Southern Europe,,150,39, 140 | Marshall Islands,MH,MHL,584,ISO 3166-2:MH,Oceania,Micronesia,,9,57, 141 | Martinique,MQ,MTQ,474,ISO 3166-2:MQ,Americas,Latin America and the Caribbean,Caribbean,19,419,29 142 | Mauritania,MR,MRT,478,ISO 3166-2:MR,Africa,Sub-Saharan Africa,Western Africa,2,202,11 143 | Mauritius,MU,MUS,480,ISO 3166-2:MU,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 144 | Mayotte,YT,MYT,175,ISO 3166-2:YT,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 145 | Mexico,MX,MEX,484,ISO 3166-2:MX,Americas,Latin America and the Caribbean,Central America,19,419,13 146 | Micronesia (Federated States of),FM,FSM,583,ISO 3166-2:FM,Oceania,Micronesia,,9,57, 147 | "Moldova, Republic of",MD,MDA,498,ISO 3166-2:MD,Europe,Eastern Europe,,150,151, 148 | Monaco,MC,MCO,492,ISO 3166-2:MC,Europe,Western Europe,,150,155, 149 | Mongolia,MN,MNG,496,ISO 3166-2:MN,Asia,Eastern Asia,,142,30, 150 | Montenegro,ME,MNE,499,ISO 3166-2:ME,Europe,Southern Europe,,150,39, 151 | Montserrat,MS,MSR,500,ISO 3166-2:MS,Americas,Latin America and the Caribbean,Caribbean,19,419,29 152 | Morocco,MA,MAR,504,ISO 3166-2:MA,Africa,Northern Africa,,2,15, 153 | Mozambique,MZ,MOZ,508,ISO 3166-2:MZ,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 154 | Myanmar,MM,MMR,104,ISO 3166-2:MM,Asia,South-eastern Asia,,142,35, 155 | Namibia,NA,NAM,516,ISO 3166-2:NA,Africa,Sub-Saharan Africa,Southern Africa,2,202,18 156 | Nauru,NR,NRU,520,ISO 3166-2:NR,Oceania,Micronesia,,9,57, 157 | Nepal,NP,NPL,524,ISO 3166-2:NP,Asia,Southern Asia,,142,34, 158 | Netherlands,NL,NLD,528,ISO 3166-2:NL,Europe,Western Europe,,150,155, 159 | New Caledonia,NC,NCL,540,ISO 3166-2:NC,Oceania,Melanesia,,9,54, 160 | New Zealand,NZ,NZL,554,ISO 3166-2:NZ,Oceania,Australia and New Zealand,,9,53, 161 | Nicaragua,NI,NIC,558,ISO 3166-2:NI,Americas,Latin America and the Caribbean,Central America,19,419,13 162 | Niger,NE,NER,562,ISO 3166-2:NE,Africa,Sub-Saharan Africa,Western Africa,2,202,11 163 | Nigeria,NG,NGA,566,ISO 3166-2:NG,Africa,Sub-Saharan Africa,Western Africa,2,202,11 164 | Niue,NU,NIU,570,ISO 3166-2:NU,Oceania,Polynesia,,9,61, 165 | Norfolk Island,NF,NFK,574,ISO 3166-2:NF,Oceania,Australia and New Zealand,,9,53, 166 | North Macedonia,MK,MKD,807,ISO 3166-2:MK,Europe,Southern Europe,,150,39, 167 | Northern Mariana Islands,MP,MNP,580,ISO 3166-2:MP,Oceania,Micronesia,,9,57, 168 | Norway,NO,NOR,578,ISO 3166-2:NO,Europe,Northern Europe,,150,154, 169 | Oman,OM,OMN,512,ISO 3166-2:OM,Asia,Western Asia,,142,145, 170 | Pakistan,PK,PAK,586,ISO 3166-2:PK,Asia,Southern Asia,,142,34, 171 | Palau,PW,PLW,585,ISO 3166-2:PW,Oceania,Micronesia,,9,57, 172 | "Palestine, State of",PS,PSE,275,ISO 3166-2:PS,Asia,Western Asia,,142,145, 173 | Panama,PA,PAN,591,ISO 3166-2:PA,Americas,Latin America and the Caribbean,Central America,19,419,13 174 | Papua New Guinea,PG,PNG,598,ISO 3166-2:PG,Oceania,Melanesia,,9,54, 175 | Paraguay,PY,PRY,600,ISO 3166-2:PY,Americas,Latin America and the Caribbean,South America,19,419,5 176 | Peru,PE,PER,604,ISO 3166-2:PE,Americas,Latin America and the Caribbean,South America,19,419,5 177 | Philippines,PH,PHL,608,ISO 3166-2:PH,Asia,South-eastern Asia,,142,35, 178 | Pitcairn,PN,PCN,612,ISO 3166-2:PN,Oceania,Polynesia,,9,61, 179 | Poland,PL,POL,616,ISO 3166-2:PL,Europe,Eastern Europe,,150,151, 180 | Portugal,PT,PRT,620,ISO 3166-2:PT,Europe,Southern Europe,,150,39, 181 | Puerto Rico,PR,PRI,630,ISO 3166-2:PR,Americas,Latin America and the Caribbean,Caribbean,19,419,29 182 | Qatar,QA,QAT,634,ISO 3166-2:QA,Asia,Western Asia,,142,145, 183 | Réunion,RE,REU,638,ISO 3166-2:RE,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 184 | Romania,RO,ROU,642,ISO 3166-2:RO,Europe,Eastern Europe,,150,151, 185 | Russian Federation,RU,RUS,643,ISO 3166-2:RU,Europe,Eastern Europe,,150,151, 186 | Rwanda,RW,RWA,646,ISO 3166-2:RW,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 187 | Saint Barthélemy,BL,BLM,652,ISO 3166-2:BL,Americas,Latin America and the Caribbean,Caribbean,19,419,29 188 | "Saint Helena, Ascension and Tristan da Cunha",SH,SHN,654,ISO 3166-2:SH,Africa,Sub-Saharan Africa,Western Africa,2,202,11 189 | Saint Kitts and Nevis,KN,KNA,659,ISO 3166-2:KN,Americas,Latin America and the Caribbean,Caribbean,19,419,29 190 | Saint Lucia,LC,LCA,662,ISO 3166-2:LC,Americas,Latin America and the Caribbean,Caribbean,19,419,29 191 | Saint Martin (French part),MF,MAF,663,ISO 3166-2:MF,Americas,Latin America and the Caribbean,Caribbean,19,419,29 192 | Saint Pierre and Miquelon,PM,SPM,666,ISO 3166-2:PM,Americas,Northern America,,19,21, 193 | Saint Vincent and the Grenadines,VC,VCT,670,ISO 3166-2:VC,Americas,Latin America and the Caribbean,Caribbean,19,419,29 194 | Samoa,WS,WSM,882,ISO 3166-2:WS,Oceania,Polynesia,,9,61, 195 | San Marino,SM,SMR,674,ISO 3166-2:SM,Europe,Southern Europe,,150,39, 196 | Sao Tome and Principe,ST,STP,678,ISO 3166-2:ST,Africa,Sub-Saharan Africa,Middle Africa,2,202,17 197 | Saudi Arabia,SA,SAU,682,ISO 3166-2:SA,Asia,Western Asia,,142,145, 198 | Senegal,SN,SEN,686,ISO 3166-2:SN,Africa,Sub-Saharan Africa,Western Africa,2,202,11 199 | Serbia,RS,SRB,688,ISO 3166-2:RS,Europe,Southern Europe,,150,39, 200 | Seychelles,SC,SYC,690,ISO 3166-2:SC,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 201 | Sierra Leone,SL,SLE,694,ISO 3166-2:SL,Africa,Sub-Saharan Africa,Western Africa,2,202,11 202 | Singapore,SG,SGP,702,ISO 3166-2:SG,Asia,South-eastern Asia,,142,35, 203 | Sint Maarten (Dutch part),SX,SXM,534,ISO 3166-2:SX,Americas,Latin America and the Caribbean,Caribbean,19,419,29 204 | Slovakia,SK,SVK,703,ISO 3166-2:SK,Europe,Eastern Europe,,150,151, 205 | Slovenia,SI,SVN,705,ISO 3166-2:SI,Europe,Southern Europe,,150,39, 206 | Solomon Islands,SB,SLB,90,ISO 3166-2:SB,Oceania,Melanesia,,9,54, 207 | Somalia,SO,SOM,706,ISO 3166-2:SO,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 208 | South Africa,ZA,ZAF,710,ISO 3166-2:ZA,Africa,Sub-Saharan Africa,Southern Africa,2,202,18 209 | South Georgia and the South Sandwich Islands,GS,SGS,239,ISO 3166-2:GS,Americas,Latin America and the Caribbean,South America,19,419,5 210 | South Sudan,SS,SSD,728,ISO 3166-2:SS,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 211 | Spain,ES,ESP,724,ISO 3166-2:ES,Europe,Southern Europe,,150,39, 212 | Sri Lanka,LK,LKA,144,ISO 3166-2:LK,Asia,Southern Asia,,142,34, 213 | Sudan,SD,SDN,729,ISO 3166-2:SD,Africa,Northern Africa,,2,15, 214 | Suriname,SR,SUR,740,ISO 3166-2:SR,Americas,Latin America and the Caribbean,South America,19,419,5 215 | Svalbard and Jan Mayen,SJ,SJM,744,ISO 3166-2:SJ,Europe,Northern Europe,,150,154, 216 | Sweden,SE,SWE,752,ISO 3166-2:SE,Europe,Northern Europe,,150,154, 217 | Switzerland,CH,CHE,756,ISO 3166-2:CH,Europe,Western Europe,,150,155, 218 | Syrian Arab Republic,SY,SYR,760,ISO 3166-2:SY,Asia,Western Asia,,142,145, 219 | "Taiwan, Province of China",TW,TWN,158,ISO 3166-2:TW,Asia,Eastern Asia,,142,30, 220 | Tajikistan,TJ,TJK,762,ISO 3166-2:TJ,Asia,Central Asia,,142,143, 221 | "Tanzania, United Republic of",TZ,TZA,834,ISO 3166-2:TZ,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 222 | Thailand,TH,THA,764,ISO 3166-2:TH,Asia,South-eastern Asia,,142,35, 223 | Timor-Leste,TL,TLS,626,ISO 3166-2:TL,Asia,South-eastern Asia,,142,35, 224 | Togo,TG,TGO,768,ISO 3166-2:TG,Africa,Sub-Saharan Africa,Western Africa,2,202,11 225 | Tokelau,TK,TKL,772,ISO 3166-2:TK,Oceania,Polynesia,,9,61, 226 | Tonga,TO,TON,776,ISO 3166-2:TO,Oceania,Polynesia,,9,61, 227 | Trinidad and Tobago,TT,TTO,780,ISO 3166-2:TT,Americas,Latin America and the Caribbean,Caribbean,19,419,29 228 | Tunisia,TN,TUN,788,ISO 3166-2:TN,Africa,Northern Africa,,2,15, 229 | Turkey,TR,TUR,792,ISO 3166-2:TR,Asia,Western Asia,,142,145, 230 | Turkmenistan,TM,TKM,795,ISO 3166-2:TM,Asia,Central Asia,,142,143, 231 | Turks and Caicos Islands,TC,TCA,796,ISO 3166-2:TC,Americas,Latin America and the Caribbean,Caribbean,19,419,29 232 | Tuvalu,TV,TUV,798,ISO 3166-2:TV,Oceania,Polynesia,,9,61, 233 | Uganda,UG,UGA,800,ISO 3166-2:UG,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 234 | Ukraine,UA,UKR,804,ISO 3166-2:UA,Europe,Eastern Europe,,150,151, 235 | United Arab Emirates,AE,ARE,784,ISO 3166-2:AE,Asia,Western Asia,,142,145, 236 | United Kingdom of Great Britain and Northern Ireland,GB,GBR,826,ISO 3166-2:GB,Europe,Northern Europe,,150,154, 237 | United States of America,US,USA,840,ISO 3166-2:US,Americas,Northern America,,19,21, 238 | United States Minor Outlying Islands,UM,UMI,581,ISO 3166-2:UM,Oceania,Micronesia,,9,57, 239 | Uruguay,UY,URY,858,ISO 3166-2:UY,Americas,Latin America and the Caribbean,South America,19,419,5 240 | Uzbekistan,UZ,UZB,860,ISO 3166-2:UZ,Asia,Central Asia,,142,143, 241 | Vanuatu,VU,VUT,548,ISO 3166-2:VU,Oceania,Melanesia,,9,54, 242 | Venezuela (Bolivarian Republic of),VE,VEN,862,ISO 3166-2:VE,Americas,Latin America and the Caribbean,South America,19,419,5 243 | Viet Nam,VN,VNM,704,ISO 3166-2:VN,Asia,South-eastern Asia,,142,35, 244 | Virgin Islands (British),VG,VGB,92,ISO 3166-2:VG,Americas,Latin America and the Caribbean,Caribbean,19,419,29 245 | Virgin Islands (U.S.),VI,VIR,850,ISO 3166-2:VI,Americas,Latin America and the Caribbean,Caribbean,19,419,29 246 | Wallis and Futuna,WF,WLF,876,ISO 3166-2:WF,Oceania,Polynesia,,9,61, 247 | Western Sahara,EH,ESH,732,ISO 3166-2:EH,Africa,Northern Africa,,2,15, 248 | Yemen,YE,YEM,887,ISO 3166-2:YE,Asia,Western Asia,,142,145, 249 | Zambia,ZM,ZMB,894,ISO 3166-2:ZM,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 250 | Zimbabwe,ZW,ZWE,716,ISO 3166-2:ZW,Africa,Sub-Saharan Africa,Eastern Africa,2,202,14 -------------------------------------------------------------------------------- /Chapter_06/csv/currency_ISO_4217.csv: -------------------------------------------------------------------------------- 1 | AlphabeticCode,NumericCode,DecimalDigits,CurrencyName,Locations 2 | AED,784,2,United Arab Emirates dirham, United Arab Emirates 3 | AFN,971,2,Afghan afghani, Afghanistan 4 | ALL,8,2,Albanian lek, Albania 5 | AMD,51,2,Armenian dram, Armenia 6 | ANG,532,2,Netherlands Antillean guilder," Curaçao (CW),  Sint Maarten (SX)" 7 | AOA,973,2,Angolan kwanza, Angola 8 | ARS,32,2,Argentine peso, Argentina 9 | AUD,36,2,Australian dollar," Australia,  Christmas Island (CX),  Cocos (Keeling) Islands (CC),  Heard Island and McDonald Islands (HM),  Kiribati (KI),  Nauru (NR),  Norfolk Island (NF),  Tuvalu (TV)" 10 | AWG,533,2,Aruban florin, Aruba 11 | AZN,944,2,Azerbaijani manat, Azerbaijan 12 | BAM,977,2,Bosnia and Herzegovina convertible mark, Bosnia and Herzegovina 13 | BBD,52,2,Barbados dollar, Barbados 14 | BDT,50,2,Bangladeshi taka, Bangladesh 15 | BGN,975,2,Bulgarian lev, Bulgaria 16 | BHD,48,3,Bahraini dinar, Bahrain 17 | BIF,108,0,Burundian franc, Burundi 18 | BMD,60,2,Bermudian dollar, Bermuda 19 | BND,96,2,Brunei dollar, Brunei 20 | BOB,68,2,Boliviano, Bolivia 21 | BOV,984,2,Bolivian Mvdol (funds code), Bolivia 22 | BRL,986,2,Brazilian real, Brazil 23 | BSD,44,2,Bahamian dollar, Bahamas 24 | BTN,64,2,Bhutanese ngultrum, Bhutan 25 | BWP,72,2,Botswana pula, Botswana 26 | BYN,933,2,Belarusian ruble, Belarus 27 | BZD,84,2,Belize dollar, Belize 28 | CAD,124,2,Canadian dollar, Canada 29 | CDF,976,2,Congolese franc, Democratic Republic of the Congo 30 | CHE,947,2,WIR Euro (complementary currency),  Switzerland 31 | CHF,756,2,Swiss franc,"  Switzerland,  Liechtenstein (LI)" 32 | CHW,948,2,WIR Franc (complementary currency),  Switzerland 33 | CLF,990,4,Unidad de Fomento (funds code), Chile 34 | CLP,152,0,Chilean peso, Chile 35 | CNY,156,2,Chinese yuan[7], China 36 | COP,170,2,Colombian peso, Colombia 37 | COU,970,2,Unidad de Valor Real (UVR) (funds code)[8], Colombia 38 | CRC,188,2,Costa Rican colon, Costa Rica 39 | CUC,931,2,Cuban convertible peso, Cuba 40 | CUP,192,2,Cuban peso, Cuba 41 | CVE,132,2,Cape Verdean escudo, Cabo Verde 42 | CZK,203,2,Czech koruna, Czechia [9] 43 | DJF,262,0,Djiboutian franc, Djibouti 44 | DKK,208,2,Danish krone," Denmark,  Faroe Islands (FO),  Greenland (GL)" 45 | DOP,214,2,Dominican peso, Dominican Republic 46 | DZD,12,2,Algerian dinar, Algeria 47 | EGP,818,2,Egyptian pound, Egypt 48 | ERN,232,2,Eritrean nakfa, Eritrea 49 | ETB,230,2,Ethiopian birr, Ethiopia 50 | EUR,978,2,Euro," Åland Islands (AX),  European Union (EU),  Andorra (AD),  Austria (AT),  Belgium (BE),  Cyprus (CY),  Estonia (EE),  Finland (FI),  France (FR),  French Southern and Antarctic Lands (TF),  Germany (DE),  Greece (GR),  Guadeloupe (GP),  Ireland (IE),  Italy (IT),  Kosovo (XK),  Latvia (LV),  Lithuania (LT),  Luxembourg (LU),  Malta (MT),  French Guiana (GF),  Martinique (MQ),  Mayotte (YT),  Monaco (MC),  Montenegro (ME),  Netherlands (NL),  Portugal (PT),  Réunion (RE),  Saint Barthélemy (BL),  Saint Martin (MF),  Saint Pierre and Miquelon (PM),  San Marino (SM),  Slovakia (SK),  Slovenia (SI),  Spain (ES),   Vatican City (VA)" 51 | FJD,242,2,Fiji dollar, Fiji 52 | FKP,238,2,Falkland Islands pound, Falkland Islands (pegged to GBP 1:1) 53 | GBP,826,2,Pound sterling," United Kingdom,  British Indian Ocean Territory (IO) (also uses USD), the  Isle of Man (IM, see Manx pound),  Jersey (JE, see Jersey pound), and  Guernsey (GG, see Guernsey pound)" 54 | GEL,981,2,Georgian lari, Georgia 55 | GHS,936,2,Ghanaian cedi, Ghana 56 | GIP,292,2,Gibraltar pound, Gibraltar (pegged to GBP 1:1) 57 | GMD,270,2,Gambian dalasi, Gambia 58 | GNF,324,0,Guinean franc, Guinea 59 | GTQ,320,2,Guatemalan quetzal, Guatemala 60 | GYD,328,2,Guyanese dollar, Guyana 61 | HKD,344,2,Hong Kong dollar, Hong Kong 62 | HNL,340,2,Honduran lempira, Honduras 63 | HRK,191,2,Croatian kuna, Croatia 64 | HTG,332,2,Haitian gourde, Haiti 65 | HUF,348,2,Hungarian forint, Hungary 66 | IDR,360,2,Indonesian rupiah, Indonesia 67 | ILS,376,2,Israeli new shekel," Israel,  Palestinian Authority[10]" 68 | INR,356,2,Indian rupee," India,  Bhutan" 69 | IQD,368,3,Iraqi dinar, Iraq 70 | IRR,364,2,Iranian rial, Iran 71 | ISK,352,0,Icelandic króna, Iceland 72 | JMD,388,2,Jamaican dollar, Jamaica 73 | JOD,400,3,Jordanian dinar, Jordan 74 | JPY,392,0,Japanese yen, Japan 75 | KES,404,2,Kenyan shilling, Kenya 76 | KGS,417,2,Kyrgyzstani som, Kyrgyzstan 77 | KHR,116,2,Cambodian riel, Cambodia 78 | KMF,174,0,Comoro franc, Comoros 79 | KPW,408,2,North Korean won, North Korea 80 | KRW,410,0,South Korean won, South Korea 81 | KWD,414,3,Kuwaiti dinar, Kuwait 82 | KYD,136,2,Cayman Islands dollar, Cayman Islands 83 | KZT,398,2,Kazakhstani tenge, Kazakhstan 84 | LAK,418,2,Lao kip, Laos 85 | LBP,422,2,Lebanese pound, Lebanon 86 | LKR,144,2,Sri Lankan rupee, Sri Lanka 87 | LRD,430,2,Liberian dollar, Liberia 88 | LSL,426,2,Lesotho loti, Lesotho 89 | LYD,434,3,Libyan dinar, Libya 90 | MAD,504,2,Moroccan dirham," Morocco,  Western Sahara" 91 | MDL,498,2,Moldovan leu, Moldova 92 | MGA,969,2,Malagasy ariary, Madagascar 93 | MKD,807,2,Macedonian denar, North Macedonia 94 | MMK,104,2,Myanmar kyat, Myanmar 95 | MNT,496,2,Mongolian tögrög, Mongolia 96 | MOP,446,2,Macanese pataca, Macau 97 | MRU[11],929,2,Mauritanian ouguiya, Mauritania 98 | MUR,480,2,Mauritian rupee, Mauritius 99 | MVR,462,2,Maldivian rufiyaa, Maldives 100 | MWK,454,2,Malawian kwacha, Malawi 101 | MXN,484,2,Mexican peso, Mexico 102 | MXV,979,2,Mexican Unidad de Inversion (UDI) (funds code), Mexico 103 | MYR,458,2,Malaysian ringgit, Malaysia 104 | MZN,943,2,Mozambican metical, Mozambique 105 | NAD,516,2,Namibian dollar, Namibia 106 | NGN,566,2,Nigerian naira, Nigeria 107 | NIO,558,2,Nicaraguan córdoba, Nicaragua 108 | NOK,578,2,Norwegian krone," Norway,  Svalbard and  Jan Mayen (SJ),  Bouvet Island (BV)" 109 | NPR,524,2,Nepalese rupee,   Nepal 110 | NZD,554,2,New Zealand dollar," New Zealand,  Cook Islands (CK),  Niue (NU),  Pitcairn Islands (PN; see also Pitcairn Islands dollar),  Tokelau (TK)" 111 | OMR,512,3,Omani rial, Oman 112 | PAB,590,2,Panamanian balboa, Panama 113 | PEN,604,2,Peruvian sol, Peru 114 | PGK,598,2,Papua New Guinean kina, Papua New Guinea 115 | PHP,608,2,Philippine peso[12], Philippines 116 | PKR,586,2,Pakistani rupee, Pakistan 117 | PLN,985,2,Polish złoty, Poland 118 | PYG,600,0,Paraguayan guaraní, Paraguay 119 | QAR,634,2,Qatari riyal, Qatar 120 | RON,946,2,Romanian leu, Romania 121 | RSD,941,2,Serbian dinar, Serbia 122 | RUB,643,2,Russian ruble, Russia 123 | RWF,646,0,Rwandan franc, Rwanda 124 | SAR,682,2,Saudi riyal, Saudi Arabia 125 | SBD,90,2,Solomon Islands dollar, Solomon Islands 126 | SCR,690,2,Seychelles rupee, Seychelles 127 | SDG,938,2,Sudanese pound, Sudan 128 | SEK,752,2,Swedish krona/kronor, Sweden 129 | SGD,702,2,Singapore dollar, Singapore 130 | SHP,654,2,Saint Helena pound," Saint Helena (SH-SH),  Ascension Island (SH-AC),  Tristan da Cunha" 131 | SLL,694,2,Sierra Leonean leone, Sierra Leone 132 | SOS,706,2,Somali shilling, Somalia 133 | SRD,968,2,Surinamese dollar, Suriname 134 | SSP,728,2,South Sudanese pound, South Sudan 135 | STN[13],930,2,São Tomé and Príncipe dobra, São Tomé and Príncipe 136 | SVC,222,2,Salvadoran colón, El Salvador 137 | SYP,760,2,Syrian pound, Syria 138 | SZL,748,2,Swazi lilangeni, Eswatini[12] 139 | THB,764,2,Thai baht, Thailand 140 | TJS,972,2,Tajikistani somoni, Tajikistan 141 | TMT,934,2,Turkmenistan manat, Turkmenistan 142 | TND,788,3,Tunisian dinar, Tunisia 143 | TOP,776,2,Tongan paʻanga, Tonga 144 | TRY,949,2,Turkish lira," Turkey,  Northern Cyprus" 145 | TTD,780,2,Trinidad and Tobago dollar, Trinidad and Tobago 146 | TWD,901,2,New Taiwan dollar, Taiwan 147 | TZS,834,2,Tanzanian shilling, Tanzania 148 | UAH,980,2,Ukrainian hryvnia, Ukraine 149 | UGX,800,0,Ugandan shilling, Uganda 150 | USD,840,2,United States dollar," United States,  American Samoa (AS),  Barbados (BB) (as well as Barbados Dollar),  Bermuda (BM) (as well as Bermudian Dollar),  British Indian Ocean Territory (IO) (also uses GBP),  British Virgin Islands (VG),  Caribbean Netherlands (BQ – Bonaire, Sint Eustatius and Saba),  Ecuador (EC),  El Salvador (SV),  Guam (GU),  Haiti (HT),  Marshall Islands (MH),  Federated States of Micronesia (FM),  Northern Mariana Islands (MP),  Palau (PW),  Panama (PA) (as well as Panamanian Balboa),  Puerto Rico (PR),  Timor-Leste (TL),  Turks and Caicos Islands (TC),  U.S. Virgin Islands (VI),  United States Minor Outlying Islands (UM)  Cambodia." 151 | USN,997,2,United States dollar (next day) (funds code), United States 152 | UYI,940,0,Uruguay Peso en Unidades Indexadas (URUIURUI) (funds code), Uruguay 153 | UYU,858,2,Uruguayan peso, Uruguay 154 | UYW,927,4,Unidad previsional[14], Uruguay 155 | UZS,860,2,Uzbekistan som, Uzbekistan 156 | VES,928,2,Venezuelan bolívar soberano[12], Venezuela 157 | VND,704,0,Vietnamese đồng, Vietnam 158 | VUV,548,0,Vanuatu vatu, Vanuatu 159 | WST,882,2,Samoan tala, Samoa 160 | XAF,950,0,CFA franc BEAC," Cameroon (CM),  Central African Republic (CF),  Republic of the Congo (CG),  Chad (TD),  Equatorial Guinea (GQ),  Gabon (GA)" 161 | XAG,961,,Silver (one troy ounce), 162 | XAU,959,,Gold (one troy ounce), 163 | XBA,955,,European Composite Unit (EURCO) (bond market unit), 164 | XBB,956,,European Monetary Unit (E.M.U.-6) (bond market unit), 165 | XBC,957,,European Unit of Account 9 (E.U.A.-9) (bond market unit), 166 | XBD,958,,European Unit of Account 17 (E.U.A.-17) (bond market unit), 167 | XCD,951,2,East Caribbean dollar," Anguilla (AI),  Antigua and Barbuda (AG),  Dominica (DM),  Grenada (GD),  Montserrat (MS),  Saint Kitts and Nevis (KN),  Saint Lucia (LC),  Saint Vincent and the Grenadines (VC)" 168 | XDR,960,,Special drawing rights,International Monetary Fund 169 | XOF,952,0,CFA franc BCEAO," Benin (BJ),  Burkina Faso (BF),  Côte d'Ivoire (CI),  Guinea-Bissau (GW),  Mali (ML),  Niger (NE),  Senegal (SN),  Togo (TG)" 170 | XPD,964,,Palladium (one troy ounce), 171 | XPF,953,0,CFP franc (franc Pacifique),"French territories of the Pacific Ocean:  French Polynesia (PF),  New Caledonia (NC),  Wallis and Futuna (WF)" 172 | XPT,962,,Platinum (one troy ounce), 173 | XSU,994,,SUCRE,Unified System for Regional Compensation (SUCRE)[15] 174 | XTS,963,,Code reserved for testing, 175 | XUA,965,,ADB Unit of Account,African Development Bank[16] 176 | XXX,999,,No currency, 177 | YER,886,2,Yemeni rial, Yemen 178 | ZAR,710,2,South African rand," Lesotho,  Namibia,  South Africa" 179 | ZMW,967,2,Zambian kwacha, Zambia 180 | ZWL,932,2,Zimbabwean dollar, Zimbabwe -------------------------------------------------------------------------------- /Chapter_06/csv/exchange.csv: -------------------------------------------------------------------------------- 1 | Name,ID,Country,City,Zone,Delta,DST_period,Open,Close,Lunch,Open_UTC,Close_UTC,Lunch_UTC 2 | Euronext Amsterdam,AMS,Netherlands,Amsterdam,CET,1,Mar-Oct,09:00,17:40,No,08:00,16:40,No 3 | Armenia Securities Exchange,AMX,Armenia,Yerevan,AMT,4,,10:00,15:00,No,06:00,11:00,No 4 | Amman Stock Exchange,ASE,Jordan,Amman,EET,2,Mar-Oct,10:00,12:00,No,08:00,10:00,No 5 | Australian Securities Exchange,ASX,Australia,Sydney,AEST,10,Oct-Apr,10:00,16:00,No,00:00,06:00,No 6 | Buenos Aires Stock Exchange,BCBA,Argentina,Buenos Aires,ART,_3,,11:00,17:00,No,14:00,20:00,No 7 | Spanish Stock Exchange,BME,Spain,Madrid,CET,1,Mar-Oct,09:00,17:30,No,08:00,16:30,No 8 | Mexican Stock Exchange,BMV,Mexico,Mexico City,CST,_6,Apr-Oct,08:30,15:00,No,14:30,21:00,No 9 | Bolsa de Valores de Sao Paulo,Bovespa,Brazil,Sao Paulo,BRT,_3,Suspended,10:00,17:30,No,13:00,20:00,No 10 | Euronext Brussels,BRU,Belgium,Brussels,CET,1,Mar-Oct,09:00,17:30,No,08:00,16:30,No 11 | Bombay Stock Exchange,BSE:IN,India,Mumbai,IST,5.5,,09:15,15:30,No,03:45,10:00,No 12 | Beirut Stock Exchange,BSE:LB,Lebanon,Beirut,EET,2,Mar-Oct,09:30,12:30,No,07:30,10:30,No 13 | Budapest Stock Exchange,BSE:HU,Hungary,Budapest,CET,1,Mar-Oct,09:00,17:00,No,08:00,16:00,No 14 | Bucharest Stock Exchange,BVB,Romania,Bucharest,EET,2,Mar-Oct,10:00,18:00,No,08:00,15:45,No 15 | Berne eXchange,BX,Switzerland,Berne,CET,1,Mar-Oct,09:00,16:30,No,08:00,15:30,No 16 | Colombo Stock Exchange,CSE:LK,Sri Lanka,Colombo,SLST,5.5,,09:30,14:30,No,04:00,09:00,No 17 | Chittagong Stock Exchange,CSE:BD,Bangladesh,Chittagong,BST,6,,10:30,14:30,No,04:30,08:30,No 18 | Copenhagen Stock Exchange,CSE:DK,Denmark,Copenhagen,CET,1,Mar-Oct,09:00,17:00,No,08:00,16:00,No 19 | Casablanca Stock Exchange,CSE:MA,Maroc,Casablanca,CET,0,Mar-Oct,08:10,15:55,No,08:10,15:55,No 20 | Dhaka Stock Exchange,DSE:BD,Bangladesh,Dhaka,BST,6,,10:30,14:30,No,04:30,08:30,No 21 | Dar es Salaam Stock Exchange,DSE:TZ,Tanzania,Dar es Salaam,EAT,3,,08:00,17:00,No,05:00,14:00,No 22 | Egyptian Exchange,EGX,Egypt,Cairo,EET,2,,10:00,14:30,No,08:00,12:30,No 23 | Euronext Paris,EPA,France,Paris,CET,1,Mar-Oct,09:00,17:30,No,08:00,16:30,No 24 | Eurex Exchange,EUREX,Germany,Eschborn,CET,1,Mar-Oct,08:00,22:00,No,07:00,21:00,No 25 | Frankfurt Stock Exchange (Xetra),FSX,Germany,Frankfurt,CET,1,Mar-Oct,08:00,20:00,No,07:00,19:00,No 26 | Warsaw Stock Exchange,GPW,Poland,Warsaw,CET,1,Mar-Oct,09:00,17:00,No,08:00,16:00,No 27 | Hong Kong Stock Exchange,HKEX,Hong Kong,Hong Kong,HKT,8,,09:30,16:00,12:00-13:00,01:30,08:00,04:00-05:00 28 | Hong Kong Futures Exchange,HKFE,Hong Kong,Hong Kong,HKT,8,,09:15,16:00,12:00-13:00,01:15,08:00,04:00-05:00 29 | Hanoi Stock Exchange,HNX,Vietnam,Hanoi,ICT,7,,09:00,14:45,11:30-13:00,02:00,07:45,04:30-06:00 30 | Hochiminh Stock Exchange,HOSE,Vietnam,Hochiminh,ICT,7,,09:00,14:45,11:30-13:00,02:00,07:45,04:30-06:00 31 | Indonesia Stock Exchange,IDX,Indonesia,Jakarta,WIB,7,,09:00,16:00,12:00-13:30 (Mon-Thu) 11:30-14:00 (Fri),02:00,09:00,05:00-06:30 (Mon-Thu) 04:30-07:00 (Fri) 32 | Borsa Istanbul,ISE:TR,Turkey,Istanbul,TRT,3,,10:00,18:00,13:00-14:00,07:00,15:00,10:00-11:00 33 | Irish Stock Exchange,ISE:IE,Ireland,Dublin,GMT,0,Mar-Oct,08:00,16:30,No,08:00,16:30,No 34 | Johannesburg Stock Exchange,JSE:ZA,South Africa,Johannesburg,SAST,2,,09:00,17:00,No,07:00,15:00,No 35 | Jamaica Stock Exchange,JSE:JM,Jamaica,Kingston,EST,_5,,09:00,13:00,No,13:00,17:00,No 36 | Korea Stock Exchange,KRX,South Korea,Busan & Seoul,KST,9,,09:00,15:30,No,00:00,06:30,No 37 | London Stock Exchange,LSE,United Kingdom,London,GMT,0,Mar-Oct,08:00,16:30,No,08:00,16:30,No 38 | Luxembourg Stock Exchange,LuxSE,Luxembourg,Luxembourg City,CET,1,Mar-Oct,09:00,17:35,No,08:00,16:35,No 39 | Moscow Exchange,MOEX,Russia,Moscow,MSK,3,,10:00,18:45,No,07:00,15:45,No 40 | Malta Stock Exchange,MSE,Malta,Valletta,CET,1,Mar-Oct,09:30,12:30,No,08:30,11:30,No 41 | Milan Stock Exchange,MTA,Italy,Milan,CET,1,Mar-Oct,09:00,17:35,No,08:00,16:35,No 42 | Bursa Malaysia,MYX,Malaysia,Kuala Lumpur,MYT,8,,09:00,17:00,12:30-14:30,01:00,09:00,04:30-06:30 43 | NASDAQ,NASDAQ,United States,New York,EST,_5,Mar-Nov,09:30,16:00,No,13:30,20:00,No 44 | National Stock Exchange of India,NSE:IN,India,Mumbai,IST,5.5,,09:15,15:30,No,03:45,10:00,No 45 | Nairobi Securities Exchange,NSE:KE,Kenya,Nairobi,EAT,3,,09:30,15:00,No,06:30,12:00,No 46 | Nigerian Stock Exchange,NSE:NG,Nigeria,Lagos,WAT,1,,10:00,14:20,No,09:00,15:00,No 47 | New York Stock Exchange,NYSE,United States,New York,EST,_5,Mar-Nov,09:30,16:00,No,13:30,20:00,No 48 | New Zealand Stock Market,NZSX,New Zealand,Wellington,NZST,12,Sep-Apr,10:00,16:45,No,22:00,05:00,No 49 | Helsinki Stock Exchange,OMXH,Finland,Helsinki,EET,2,Mar-Oct,10:00,18:30,No,08:00,16:30,No 50 | Riga Stock Exchange,OMXR,Latvia,Riga,EET,2,Mar-Oct,10:00,16:00,No,08:00,14:00,No 51 | Stockholm Stock Exchange,OMXS,Sweden,Stockholm,CET,1,Mar-Oct,09:00,17:30,No,08:00,16:30,No 52 | Tallinn Stock Exchange,OMXT,Estonia,Tallinn,EET,2,Mar-Oct,10:00,16:00,No,08:00,14:00,No 53 | NASDAQ OMX Vilnius,OMXV,Lithuania,Vilnius,EET,2,Mar-Oct,10:00,16:00,No,08:00,14:00,No 54 | Oslo Stock Exchange,OSE,Norway,Oslo,CET,1,Mar-Oct,09:00,16:30,No,08:00,15:30,No 55 | Philippine Stock Exchange,PSE,Philippines,Manila,PHT,8,,09:30,15:30,12:00-13:30,01:30,07:30,04:00-05:30 56 | Euronext Lisbon,PSI,Portugal,Lisbon,GMT,0,Mar-Oct,08:00,16:30,No,08:00,16:30,No 57 | Pakistan Stock Exchange,PSX,Pakistan,Karachi,PKT,5,,09:30,15:30,No,04:30,10:30,No 58 | Stock Exchange of Thailand,SET,Thailand,Bangkok,ICT,7,,10:00,16:30,12:30-14:30,03:00,09:30,05:30-07:30 59 | Singapore Exchange,SGX,Singapore,Singapore,SGT,8,,09:00,17:00,12:00-13:00,01:00,09:00,Yes 60 | Swiss Exchange,SIX,Switzerland,Zurich,CET,1,Mar-Oct,09:00,17:30,No,08:00,16:30,No 61 | Shanghai Stock Exchange,SSE,China,Shanghai,CST,8,,09:30,15:00,11:30-13:00,01:30,07:00,03:30-05:00 62 | Saint Vincent and the Grenadines Exchange,SVGEX,Saint Vincent and the Grenadines,Kingstown,AST,-4,,09:00,16:00,11:30-13:00,13:00,20:00,15:30-17:00 63 | Shenzhen Stock Exchange,SZSE,China,Shenzhen,CST,8,,09:30,15:00,11:30-13:00,01:30,07:00,03:30-05:00 64 | Saudi Stock Exchange,TADAWUL,Saudi Arabia,Riyadh,AST,3,,10:00,15:00,No,07:00,12:00,No 65 | Tel Aviv Stock Exchange,TASE,Israel,Tel Aviv,IST,2,Mar-Oct,09:00,17:30,No,07:00,15:30,No 66 | Tokyo Stock Exchange,TSE:JP,Japan,Tokyo,JST,9,,09:00,15:00,11:30-12:30,00:00,08:00,02:30-03:30 67 | Tehran Stock Exchange,TSE:IR,Iran,Tehran,IRST,3.5,,09:00,12:30,No,05:30,09:00,No 68 | Toronto Stock Exchange,TSX,Canada,Toronto,EST,_5,Mar-Nov,09:30,16:00,No,13:30,21:00,No 69 | Taiwan Stock Exchange,TWSE,Taiwan (Republic of China),Taipei,CST,8,,09:00,13:30,No,01:00,05:30,No 70 | Ukrainian Exchange,UX,Ukraine,Kiev,EET,2,Mar-Oct,10:00,17:30,No,08:00,15:30,No 71 | Wiener Börse AG,VSE,Austria,Vienna,CET,1,Mar-Oct,08:55,17:35,No,07:55,16:35,No -------------------------------------------------------------------------------- /Chapter_06/dbt/06_01_v2__dbt_project.yml: -------------------------------------------------------------------------------- 1 | 2 | # Name your project! Project 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: 'portfolio_tracking' 6 | version: '1.0.0' 7 | config-version: 2 8 | 9 | # This setting configures which "profile" dbt uses for this project. 10 | profile: 'default' 11 | 12 | # These configurations specify where dbt should look for different types of files. 13 | # The `source-paths` config, for example, states that models in this project can be 14 | # found in the "models/" directory. You probably won't need to change these! 15 | model-paths: ["models"] 16 | analysis-paths: ["analyses"] 17 | test-paths: ["tests"] 18 | seed-paths: ["seeds"] 19 | macro-paths: ["macros"] 20 | snapshot-paths: ["snapshots"] 21 | 22 | target-path: "target" # directory which will store compiled SQL files 23 | clean-targets: # directories to be removed by `dbt clean` 24 | - "target" 25 | - "dbt_packages" 26 | 27 | 28 | # Configuring models 29 | # Full documentation: https://docs.getdbt.com/docs/configuring-models 30 | 31 | # In this example config, we tell dbt to build all models in the example/ directory 32 | # as tables. These settings can be overridden in the individual model files 33 | # using the `{{ config(...) }}` macro. 34 | models: 35 | portfolio_tracking: 36 | +materialized: view 37 | 38 | staging: # Data storage layer - Applies to all files under models/staging/ 39 | +materialized: view 40 | +schema: STAGING 41 | 42 | refined: # Refined Data layer - Applies to all files under models/refined/ 43 | +materialized: table 44 | +schema: REFINED 45 | 46 | marts: # Data delivery layer - Applies to all files under models/marts 47 | portfolio: # One specific data mart - Applies to all files under models/marts/portfolio 48 | +materialized: table 49 | +schema: MART_PORTFOLIO 50 | 51 | # Configuring Snapshots 52 | # Full documentation: https://docs.getdbt.com/reference/snapshot-configs 53 | snapshots: 54 | portfolio_tracking: 55 | +target_schema: SNAPSHOTS 56 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_02_v1__STG_ABC_BANK_POSITION.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | ACCOUNTID as ACCOUNT_CODE -- TEXT 3 | , SYMBOL as SECURITY_CODE -- TEXT 4 | , DESCRIPTION as SECURITY_NAME -- TEXT 5 | , EXCHANGE as EXCHANGE_CODE -- TEXT 6 | , REPORT_DATE as REPORT_DATE -- DATE 7 | , QUANTITY as QUANTITY -- NUMBER 8 | , COST_BASE as COST_BASE -- NUMBER 9 | , POSITION_VALUE as POSITION_VALUE -- NUMBER 10 | , CURRENCY as CURRENCY_CODE -- TEXT 11 | 12 | FROM {{ source('abc_bank', 'ABC_BANK_POSITION') }} -------------------------------------------------------------------------------- /Chapter_06/dbt/06_02_v2__STG_ABC_BANK_POSITION.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | src_data as ( 4 | SELECT 5 | ACCOUNTID as ACCOUNT_CODE -- TEXT 6 | , SYMBOL as SECURITY_CODE -- TEXT 7 | , DESCRIPTION as SECURITY_NAME -- TEXT 8 | , EXCHANGE as EXCHANGE_CODE -- TEXT 9 | , REPORT_DATE as REPORT_DATE -- DATE 10 | , QUANTITY as QUANTITY -- NUMBER 11 | , COST_BASE as COST_BASE -- NUMBER 12 | , POSITION_VALUE as POSITION_VALUE -- NUMBER 13 | , CURRENCY as CURRENCY_CODE -- TEXT 14 | 15 | , 'SOURCE_DATA.ABC_BANK_POSITION' as RECORD_SOURCE 16 | 17 | FROM {{ source('abc_bank', 'ABC_BANK_POSITION') }} 18 | ), 19 | 20 | hashed as ( 21 | SELECT 22 | concat_ws('|', ACCOUNT_CODE, SECURITY_CODE) as POSITION_HKEY 23 | , concat_ws('|', ACCOUNT_CODE, SECURITY_CODE, 24 | SECURITY_NAME, EXCHANGE_CODE, REPORT_DATE, 25 | QUANTITY, COST_BASE, POSITION_VALUE, CURRENCY_CODE ) as POSITION_HDIFF 26 | , * 27 | , '{{ run_started_at }}'::timestamp as LOAD_TS_UTC 28 | FROM src_data 29 | ) 30 | 31 | SELECT * FROM hashed 32 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_02_v3__STG_ABC_BANK_POSITION.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | src_data as ( 4 | SELECT 5 | ACCOUNTID as ACCOUNT_CODE -- TEXT 6 | , SYMBOL as SECURITY_CODE -- TEXT 7 | , DESCRIPTION as SECURITY_NAME -- TEXT 8 | , EXCHANGE as EXCHANGE_CODE -- TEXT 9 | , REPORT_DATE as REPORT_DATE -- DATE 10 | , QUANTITY as QUANTITY -- NUMBER 11 | , COST_BASE as COST_BASE -- NUMBER 12 | , POSITION_VALUE as POSITION_VALUE -- NUMBER 13 | , CURRENCY as CURRENCY_CODE -- TEXT 14 | 15 | , 'SOURCE_DATA.ABC_BANK_POSITION' as RECORD_SOURCE 16 | 17 | FROM {{ source('abc_bank', 'ABC_BANK_POSITION') }} 18 | ), 19 | 20 | hashed as ( 21 | SELECT 22 | {{ dbt_utils.surrogate_key([ 'ACCOUNT_CODE', 'SECURITY_CODE']) }} as POSITION_HKEY 23 | , {{ dbt_utils.surrogate_key([ 'ACCOUNT_CODE', 'SECURITY_CODE', 24 | 'SECURITY_NAME', 'EXCHANGE_CODE', 'REPORT_DATE', 25 | 'QUANTITY', 'COST_BASE', 'POSITION_VALUE', 'CURRENCY_CODE' 26 | ]) }} as POSITION_HDIFF 27 | , * 28 | , '{{ run_started_at }}'::timestamp as LOAD_TS_UTC 29 | FROM src_data 30 | ) 31 | 32 | SELECT * FROM hashed 33 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_03_v1__REF_POSITION_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | * 3 | , POSITION_VALUE - COST_BASE as UNREALIZED_PROFIT 4 | , ROUND(UNREALIZED_PROFIT / COST_BASE, 5)*100 as UNREALIZED_PROFIT_PCT 5 | FROM {{ ref('STG_ABC_BANK_POSITION') }} 6 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_03_v2__REF_POSITION_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | current_from_snapshot as ( 4 | SELECT * 5 | FROM {{ ref('SNSH_ABC_BANK_POSITION') }} 6 | WHERE DBT_VALID_TO is null 7 | ) 8 | 9 | SELECT 10 | * 11 | , POSITION_VALUE - COST_BASE as UNREALIZED_PROFIT 12 | , ROUND(UNREALIZED_PROFIT / COST_BASE, 5)*100 as UNREALIZED_PROFIT_PCT 13 | FROM current_from_snapshot -------------------------------------------------------------------------------- /Chapter_06/dbt/06_04_v1__FACT_POSITION.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM {{ ref('REF_POSITION_ABC_BANK') }} -------------------------------------------------------------------------------- /Chapter_06/dbt/06_05_v1__SNSH_ABC_BANK_POSITION.sql: -------------------------------------------------------------------------------- 1 | {% snapshot SNSH_ABC_BANK_POSITION %} 2 | 3 | {{ 4 | config( 5 | unique_key= 'POSITION_HKEY', 6 | 7 | strategy='check', 8 | check_cols=['POSITION_HDIFF'], 9 | invalidate_hard_deletes=True, 10 | ) 11 | }} 12 | 13 | select * from {{ ref('STG_ABC_BANK_POSITION') }} 14 | 15 | {% endsnapshot %} -------------------------------------------------------------------------------- /Chapter_06/dbt/06_07_v1__ABC_Bank_SECURITY_INFO.csv: -------------------------------------------------------------------------------- 1 | SECURITY_CODE,SECURITY_NAME,SECTOR,INDUSTRY,COUNTRY,EXCHANGE 2 | TTD,"The Trading Desc, Inc.",Technology,EDP Services,US,NASDAQ 3 | GCM,GRAN COLOMBIA GOLD CORP,Basic Materials,GOLD,CA,TSE 4 | STAR,ISTAR INC,Real Estate,REIT - Diversified,US,NYSE -------------------------------------------------------------------------------- /Chapter_06/dbt/06_08_v1__STG_ABC_BANK_SECURITY_INFO.sql: -------------------------------------------------------------------------------- 1 | {{ config(materialized='ephemeral') }} 2 | 3 | WITH 4 | src_data as ( 5 | SELECT 6 | SECURITY_CODE as SECURITY_CODE -- TEXT 7 | , SECURITY_NAME as SECURITY_NAME -- TEXT 8 | , SECTOR as SECTOR_NAME -- TEXT 9 | , INDUSTRY as INDUSTRY_NAME -- TEXT 10 | , COUNTRY as COUNTRY_CODE -- TEXT 11 | , EXCHANGE as EXCHANGE_CODE -- TEXT 12 | , LOAD_TS as LOAD_TS -- TIMESTAMP_NTZ 13 | 14 | , 'SEED.ABC_Bank_SECURITY_INFO' as RECORD_SOURCE 15 | 16 | FROM {{ source('seeds', 'ABC_Bank_SECURITY_INFO') }} 17 | ), 18 | 19 | default_record as ( 20 | SELECT 21 | '-1' as SECURITY_CODE 22 | , 'Missing' as SECURITY_NAME 23 | , 'Missing' as SECTOR_NAME 24 | , 'Missing' as INDUSTRY_NAME 25 | , '-1' as COUNTRY_CODE 26 | , '-1' as EXCHANGE_CODE 27 | , '2020-01-01' as LOAD_TS_UTC 28 | , 'Missing' as RECORD_SOURCE 29 | ), 30 | 31 | with_default_record as( 32 | SELECT * FROM src_data 33 | UNION ALL 34 | SELECT * FROM default_record 35 | ), 36 | 37 | hashed as ( 38 | SELECT 39 | concat_ws('|', SECURITY_CODE) as SECURITY_HKEY 40 | , concat_ws('|', SECURITY_CODE, SECURITY_NAME, SECTOR_NAME, 41 | INDUSTRY_NAME, COUNTRY_CODE, EXCHANGE_CODE ) as SECURITY_HDIFF 42 | 43 | , * EXCLUDE LOAD_TS 44 | , LOAD_TS as LOAD_TS_UTC 45 | FROM with_default_record 46 | ) 47 | SELECT * FROM hashed 48 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_09_v1__SNSH_ABC_BANK_SECURITY_INFO.sql: -------------------------------------------------------------------------------- 1 | {% snapshot SNSH_ABC_BANK_SECURITY_INFO %} 2 | 3 | {{ 4 | config( 5 | unique_key= 'SECURITY_HKEY', 6 | 7 | strategy='check', 8 | check_cols=['SECURITY_HDIFF'], 9 | ) 10 | }} 11 | 12 | select * from {{ ref('STG_ABC_BANK_SECURITY_INFO') }} 13 | 14 | {% endsnapshot %} -------------------------------------------------------------------------------- /Chapter_06/dbt/06_10_v1__REF_ABC_BANK_SECURITY_INFO.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | current_from_snapshot as ( 3 | SELECT * EXCLUDE (DBT_SCD_ID, DBT_UPDATED_AT, DBT_VALID_FROM, DBT_VALID_TO) 4 | FROM {{ ref('SNSH_ABC_BANK_SECURITY_INFO') }} 5 | WHERE DBT_VALID_TO is null 6 | ) 7 | SELECT * 8 | FROM current_from_snapshot -------------------------------------------------------------------------------- /Chapter_06/dbt/06_11_v1__DIM_SECURITY.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM {{ ref('REF_ABC_BANK_SECURITY_INFO') }} -------------------------------------------------------------------------------- /Chapter_06/dbt/06_12_v1__source_seed.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | sources: 3 | - name: seeds 4 | schema: "{{target.schema}}_SEED_DATA" 5 | tables: 6 | - name: ABC_Bank_SECURITY_INFO 7 | 8 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_13_v1__source_abc_bank.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | sources: 4 | 5 | - name: abc_bank 6 | 7 | database: PORTFOLIO_TRACKING 8 | schema: SOURCE_DATA 9 | 10 | tables: 11 | - name: ABC_BANK_POSITION 12 | description: The landing table holding the data imported from the CSV extracted by ABC Bank. 13 | columns: 14 | - name: ACCOUNTID 15 | description: The code for the account at the ABC Bank. 16 | tests: 17 | - not_null 18 | - name: SYMBOL 19 | description: The symbol of the security for the ABC Bank. 20 | tests: 21 | - unique 22 | - not_null 23 | - name: DESCRIPTION 24 | description: The name of the security at the ABC Bank. 25 | tests: 26 | - not_null 27 | - name: EXCHANGE 28 | description: The short name or code of the exchange where the security is traded. 29 | tests: 30 | - not_null 31 | - name: REPORT_DATE 32 | description: > 33 | The date of the portfolio report extracted by ABC Bank. 34 | We consider this position to be the effective from this date forward, until a change is seen. 35 | tests: 36 | - not_null 37 | - name: QUANTITY 38 | description: The number of securities we hold in the portfolio at ABC Bank at the Report Date. 39 | tests: 40 | - not_null 41 | - name: COST_BASE 42 | description: The cost we paid attributable to the securities we hold in the portfolio at ABC Bank at the Report Date. 43 | tests: 44 | - not_null 45 | - name: POSITION_VALUE 46 | description: The value of the securities we hold in the portfolio at ABC Bank acording to market quotation on the Report Date. 47 | tests: 48 | - not_null 49 | - name: CURRENCY 50 | description: The currency for the monetary amounts of the position. 51 | tests: 52 | - not_null 53 | 54 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_14_v1__refined.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | 5 | - name: REF_POSITION_ABC_BANK 6 | description: The positions we have in the ABC Bank portfolio. 7 | columns: 8 | - name: UNREALIZED_PROFIT 9 | description: The unrealized profit on the position. 10 | tests: 11 | - not_null 12 | 13 | - name: UNREALIZED_PROFIT_PCT 14 | description: The unrealized profit percentaage on the position. 15 | tests: 16 | - not_null 17 | -------------------------------------------------------------------------------- /Chapter_06/dbt/06_15_v1__README.md: -------------------------------------------------------------------------------- 1 | # Welcome to the Portfolio tracking dbt project! 2 | 3 | This is sample project built with dbt and Snowflake used in the book "Data Architecture with dbt". 4 | 5 | ## Project description 6 | 7 | An investor has portfolios at different brokers where he holds positions in securities. 8 | He can buy and sell securities, therefore opening, closing and changing the positions he has. 9 | He would like to be able to provide the data he receives from the brokers to track the daily value of his overall situation 10 | and analyse his holdings according to multiple attributes of the securities. 11 | 12 | 13 | ### Running the project 14 | 15 | Try running the following commands: 16 | - dbt seed 17 | - dbt snapshot 18 | - dbt run 19 | - dbt test 20 | 21 | 22 | ### Resources: 23 | - Learn more about [the book](https://docs.getdbt.com/docs/introduction) 24 | - Learn more about [the author](https://robertozagni.com/) 25 | -------------------------------------------------------------------------------- /Chapter_06/patterns/06_06_v1__STG_Model.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | src_data as ( … ), 3 | default_record as ( … ), 4 | with_default_record as( 5 | SELECT * FROM src_data 6 | UNION ALL 7 | SELECT * FROM default_record 8 | ), 9 | hashed as ( … ) 10 | SELECT * FROM hashed 11 | -------------------------------------------------------------------------------- /Chapter_07/dbt/07_01_v1__this_with_filter.sql: -------------------------------------------------------------------------------- 1 | {% macro this_with_filter(arg1, arg2='XXXX') %} 2 | SELECT * FROM {{this}} 3 | {% if arg1 %} 4 | WHERE {{arg1}} = {{arg2}} 5 | {% endif %} 6 | {% endmacro %} -------------------------------------------------------------------------------- /Chapter_07/dbt/07_02_v1__current_from_snapshot.sql: -------------------------------------------------------------------------------- 1 | {% macro current_from_snapshot(snsh_ref) %} 2 | SELECT 3 | * EXCLUDE (DBT_SCD_ID, DBT_VALID_FROM, DBT_VALID_TO) 4 | RENAME (DBT_UPDATED_AT as SNSH_LOAD_TS_UTC ) 5 | FROM {{ snsh_ref }} 6 | WHERE DBT_VALID_TO is null 7 | {% endmacro %} -------------------------------------------------------------------------------- /Chapter_07/dbt/07_02_v2__current_from_snapshot.sql: -------------------------------------------------------------------------------- 1 | {% macro current_from_snapshot(snsh_ref, output_load_ts = true) %} 2 | 3 | SELECT 4 | * EXCLUDE (DBT_SCD_ID, DBT_VALID_FROM, DBT_VALID_TO, DBT_UPDATED_AT) 5 | {% if output_load_ts %}, DBT_UPDATED_AT as SNSH_LOAD_TS_UTC {% endif%} 6 | FROM {{ snsh_ref }} 7 | WHERE DBT_VALID_TO is null 8 | 9 | {% endmacro %} -------------------------------------------------------------------------------- /Chapter_07/dbt/07_03_v1__REF_POSITION_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | current_from_snapshot as ( 4 | {{ current_from_snapshot( 5 | snsh_ref = ref('SNSH_ABC_BANK_POSITION') 6 | ) }} 7 | ) 8 | 9 | SELECT 10 | * 11 | , POSITION_VALUE - COST_BASE as UNREALIZED_PROFIT 12 | , ROUND(UNREALIZED_PROFIT / COST_BASE, 5)*100 as UNREALIZED_PROFIT_PCT 13 | FROM current_from_snapshot -------------------------------------------------------------------------------- /Chapter_07/dbt/07_03_v2__REF_POSITION_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | current_from_snapshot as ( 4 | {{ current_from_snapshot( 5 | snsh_ref = ref('SNSH_ABC_BANK_POSITION'), 6 | output_load_ts = false 7 | ) }} 8 | ) 9 | 10 | SELECT 11 | * 12 | , POSITION_VALUE - COST_BASE as UNREALIZED_PROFIT 13 | , ROUND(UNREALIZED_PROFIT / COST_BASE, 5)*100 as UNREALIZED_PROFIT_PCT 14 | FROM current_from_snapshot -------------------------------------------------------------------------------- /Chapter_07/dbt/07_04_v1__REF_ABC_BANK_SECURITY_INFO.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | current_from_snapshot as ( 3 | {{ current_from_snapshot( snsh_ref = ref('SNSH_ABC_BANK_SECURITY_INFO') ) }} 4 | ) 5 | SELECT * 6 | FROM current_from_snapshot 7 | -------------------------------------------------------------------------------- /Chapter_07/dbt/07_05_v1__STG_ABC_BANK_POSITION.sql: -------------------------------------------------------------------------------- 1 | {{ config(materialized='ephemeral') }} 2 | 3 | WITH 4 | 5 | src_data as ( 6 | SELECT 7 | ACCOUNTID as ACCOUNT_CODE -- TEXT 8 | , SYMBOL as SECURITY_CODE -- TEXT 9 | , DESCRIPTION as SECURITY_NAME -- TEXT 10 | , EXCHANGE as EXCHANGE_CODE -- TEXT 11 | , {{to_21st_century_date('REPORT_DATE')}} as REPORT_DATE -- DATE 12 | , QUANTITY as QUANTITY -- NUMBER 13 | , COST_BASE as COST_BASE -- NUMBER 14 | , POSITION_VALUE as POSITION_VALUE -- NUMBER 15 | , CURRENCY as CURRENCY_CODE -- TEXT 16 | 17 | , 'SOURCE_DATA.ABC_BANK_POSITION' as RECORD_SOURCE 18 | 19 | FROM {{ source('abc_bank', 'ABC_BANK_POSITION') }} 20 | ), 21 | 22 | hashed as ( 23 | SELECT 24 | {{ dbt_utils.surrogate_key(['ACCOUNT_CODE', 'SECURITY_CODE']) }} as POSITION_HKEY 25 | , {{ dbt_utils.surrogate_key([ 'ACCOUNT_CODE', 'SECURITY_CODE', 26 | 'SECURITY_NAME', 'EXCHANGE_CODE', 'REPORT_DATE', 27 | 'QUANTITY', 'COST_BASE', 'POSITION_VALUE', 'CURRENCY_CODE' ]) 28 | }} as POSITION_HDIFF 29 | , * 30 | , '{{ run_started_at }}' as LOAD_TS_UTC 31 | FROM src_data 32 | ) 33 | 34 | SELECT * FROM hashed 35 | -------------------------------------------------------------------------------- /Chapter_09/dbt/09_01_v1__has_default_key.sql: -------------------------------------------------------------------------------- 1 | {% test has_default_key ( model 2 | , column_name 3 | , default_key_value = '-1' 4 | , record_source_field_name = 'RECORD_SOURCE' 5 | , default_key_record_source = 'System.DefaultKey' 6 | ) -%} 7 | 8 | {{ config(severity = 'error') }} 9 | 10 | WITH 11 | default_key_rows as ( 12 | SELECT distinct {{column_name}}, {{record_source_field_name}} 13 | FROM {{ model }} 14 | WHERE {{column_name}} = '{{default_key_value}}' 15 | and {{record_source_field_name}} = '{{default_key_record_source}}' 16 | ), 17 | 18 | validation_errors as ( 19 | SELECT '{{default_key_value}}' as {{column_name}}, '{{default_key_record_source}}' as {{record_source_field_name}} 20 | EXCEPT 21 | SELECT {{column_name}}, {{record_source_field_name}} FROM default_key_rows 22 | ) 23 | 24 | SELECT * FROM validation_errors 25 | 26 | {%- endtest %} -------------------------------------------------------------------------------- /Chapter_09/dbt/09_02_v1__warn_on_multiple_default_key.sql: -------------------------------------------------------------------------------- 1 | {% test warn_on_multiple_default_key ( model 2 | , column_name 3 | , default_key_value = '-1' 4 | , record_source_field_name = 'RECORD_SOURCE' 5 | , default_key_record_source = 'System.DefaultKey' 6 | ) -%} 7 | 8 | {{ config(severity = 'warn') }} 9 | 10 | WITH 11 | 12 | validation_errors as ( 13 | SELECT distinct {{column_name}}, {{record_source_field_name}} 14 | FROM {{ model }} 15 | WHERE {{column_name}} != '{{default_key_value}}' 16 | and {{record_source_field_name}} = '{{default_key_record_source}}' 17 | ) 18 | 19 | SELECT * FROM validation_errors 20 | 21 | {%- endtest %} -------------------------------------------------------------------------------- /Chapter_12/dbt/12_02_v1__exp_portfolio_report.md: -------------------------------------------------------------------------------- 1 | {% docs exp_portfolio_report %} 2 | 3 | # Portfolio report 4 | 5 | The Portfolio report features are: 6 | * list all positions by account 7 | * provide up to date valorization of positions. 8 | The value is available 9 | * in the position currency, depending on the exchange 10 | * in the account base currency, as set by the owner 11 | 12 | 13 | {% enddocs %} -------------------------------------------------------------------------------- /Chapter_12/dbt/12_02_v1__exp_portfolio_report.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | exposures: 4 | 5 | - name: portfolio_report 6 | type: dashboard 7 | maturity: low 8 | # url: https://xxxx/reports/portfolio_report 9 | description: | 10 | The basic portfolio report to know the positions by account. 11 | 12 | {{ doc('exp_portfolio_report') }} 13 | 14 | depends_on: 15 | - ref('FACT_POSITION') 16 | - ref('DIM_SECURITY') 17 | 18 | owner: 19 | name: Roberto 20 | email: rz70rz70@gmail.com 21 | -------------------------------------------------------------------------------- /Chapter_13/dbt/macros/13_01_v1__save_history.sql: -------------------------------------------------------------------------------- 1 | {% macro save_history( 2 | input_rel, 3 | key_column, 4 | diff_column, 5 | load_ts_column = 'LOAD_TS_UTC', 6 | input_filter_expr = 'true', 7 | history_filter_expr = 'true', 8 | high_watermark_column = none, 9 | high_watermark_test = '>=', 10 | order_by_expr = none 11 | ) -%} 12 | 13 | {{ config(materialized='incremental') }} 14 | 15 | WITH 16 | 17 | {%- if is_incremental() %} 18 | current_from_history as ( 19 | {{current_from_history( 20 | history_rel = this, 21 | key_column = key_column, 22 | selection_expr = diff_column, 23 | load_ts_column = load_ts_column, 24 | history_filter_expr = history_filter_expr 25 | ) }} 26 | ), 27 | 28 | load_from_input as ( 29 | SELECT i.* 30 | FROM {{input_rel}} as i 31 | LEFT OUTER JOIN current_from_history as h ON h.{{diff_column}} = i.{{diff_column}} 32 | WHERE h.{{diff_column}} is null 33 | and {{input_filter_expr}} 34 | {%- if high_watermark_column %} 35 | and {{high_watermark_column}} {{high_watermark_test}} (select max({{high_watermark_column}}) from {{ this }}) 36 | {%- endif %} 37 | ) 38 | 39 | {%- else %} 40 | load_from_input as ( 41 | SELECT * 42 | FROM {{input_rel}} 43 | WHERE {{input_filter_expr}} 44 | ) 45 | {%- endif %} 46 | 47 | SELECT * FROM load_from_input 48 | {%- if order_by_expr %} 49 | ORDER BY {{order_by_expr}} 50 | {%- endif %} 51 | 52 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_13/dbt/macros/13_01_v1__save_history__outline.sql: -------------------------------------------------------------------------------- 1 | {% macro save_history( 2 | input_rel, 3 | key_column, 4 | diff_column, 5 | ) -%} -- ... the other params are to improve performance 6 | 7 | {{ config(materialized='incremental') }} 8 | 9 | WITH 10 | 11 | {%- if is_incremental() %} 12 | current_from_history as ( 13 | -- get the current HDIFF for each HKEY 14 | ), 15 | 16 | load_from_input as ( 17 | -- join the input with the HIST on the HDIFF column 18 | -- and keep the rows where there is no match 19 | ) 20 | 21 | {%- else %} 22 | load_from_input as ( 23 | -- load all from the input 24 | ) 25 | {%- endif %} 26 | 27 | SELECT * FROM load_from_input 28 | -- ORDER BY option to optimize writes 29 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_13/dbt/macros/13_02_v1__current_from_history.sql: -------------------------------------------------------------------------------- 1 | {% macro current_from_history( 2 | history_rel, 3 | key_column, 4 | selection_expr = '*', 5 | load_ts_column = 'LOAD_TS_UTC', 6 | history_filter_expr = 'true', 7 | qualify_function = 'row_number' 8 | ) -%} 9 | 10 | SELECT {{selection_expr}} 11 | FROM {{history_rel}} 12 | WHERE {{history_filter_expr}} 13 | QUALIFY {{qualify_function}}() OVER( PARTITION BY {{key_column}} ORDER BY {{load_ts_column}} desc) = 1 14 | 15 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_13/dbt/models/13_03_v1__HIST_ABC_BANK_POSITION.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ save_history( 3 | input_rel = ref('STG_ABC_BANK_POSITION'), 4 | key_column = 'POSITION_HKEY', 5 | diff_column = 'POSITION_HDIFF', 6 | ) }} 7 | -- load_ts_column = 'LOAD_TS_UTC', 8 | -- input_filter_expr = 'true', 9 | -- history_filter_expr = 'true', 10 | -- high_watermark_column = none, 11 | -- high_watermark_test = '>=', 12 | -- order_by_expr = 'POSITION_HKEY' 13 | 14 | -------------------------------------------------------------------------------- /Chapter_13/dbt/models/13_04_v1__HIST_ABC_BANK_SECURITY_INFO.sql: -------------------------------------------------------------------------------- 1 | 2 | {{ save_history( 3 | input_rel = ref('STG_ABC_BANK_SECURITY_INFO'), 4 | key_column = 'SECURITY_HKEY', 5 | diff_column = 'SECURITY_HDIFF', 6 | ) }} -------------------------------------------------------------------------------- /Chapter_14/dbt/analysis/14_12_v1__SRC_POSITION_init.sql: -------------------------------------------------------------------------------- 1 | create or replace table PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION 2 | ( 3 | ACCOUNTID VARCHAR, 4 | SYMBOL VARCHAR, 5 | DESCRIPTION VARCHAR, 6 | EXCHANGE VARCHAR, 7 | REPORT_DATE DATE, 8 | QUANTITY NUMBER, 9 | COST_BASE NUMBER(38,5), 10 | POSITION_VALUE NUMBER(38,5), 11 | CURRENCY VARCHAR 12 | ) 13 | stage_file_format = (FORMAT_NAME = '\"PORTFOLIO_TRACKING\".\"SOURCE_DATA\".\"ABC_BANK_CSV_FILE_FORMAT\"') 14 | stage_copy_options = (PURGE = true); 15 | 16 | -- INSERT INTO PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION (ACCOUNTID, SYMBOL, DESCRIPTION, EXCHANGE, REPORT_DATE, QUANTITY, COST_BASE, POSITION_VALUE, CURRENCY) VALUES ('ABC000123', 'GCM', 'GRAN COLOMBIA GOLD CORP', 'TSE', '0021-04-09', 100, 559.00000, 678.00000, 'CAD'); 17 | -- INSERT INTO PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION (ACCOUNTID, SYMBOL, DESCRIPTION, EXCHANGE, REPORT_DATE, QUANTITY, COST_BASE, POSITION_VALUE, CURRENCY) VALUES ('ABC000123', 'TTD', 'TRADE DESK INC/THE -CLASS A', 'NASDAQ', '0021-04-09', 10, 5310.45000, 6925.60000, 'USD'); 18 | -- INSERT INTO PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION (ACCOUNTID, SYMBOL, DESCRIPTION, EXCHANGE, REPORT_DATE, QUANTITY, COST_BASE, POSITION_VALUE, CURRENCY) VALUES ('ABC000123', 'STAR', 'ISTAR INC', 'NYSE', '0021-04-09', 150, 2444.00000, 2725.50000, 'USD'); 19 | INSERT INTO PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION 20 | (ACCOUNTID, SYMBOL, DESCRIPTION, EXCHANGE, REPORT_DATE, QUANTITY, COST_BASE, POSITION_VALUE, CURRENCY) 21 | VALUES 22 | ('ABC000123', 'GCM', 'GRAN COLOMBIA GOLD CORP', 'TSE', '0021-04-09', 100, 559.00000, 678.00000, 'CAD') 23 | , ('ABC000123', 'TTD', 'TRADE DESK INC/THE -CLASS A', 'NASDAQ', '0021-04-09', 10, 5310.45000, 6925.60000, 'USD') 24 | , ('ABC000123', 'STAR', 'ISTAR INC', 'NYSE', '0021-04-09', 150, 2444.00000, 2725.50000, 'USD'); 25 | 26 | SELECT 1 27 | limit 100 -------------------------------------------------------------------------------- /Chapter_14/dbt/analysis/14_13_v1__SRC_POSITION_v2.sql: -------------------------------------------------------------------------------- 1 | DELETE FROM PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION 2 | WHERE ACCOUNTID='ABC000123' and SYMBOL IN ('GCM', 'SAFE', 'STAR'); 3 | 4 | INSERT INTO PORTFOLIO_TRACKING.SOURCE_DATA.ABC_BANK_POSITION 5 | (ACCOUNTID, SYMBOL, DESCRIPTION, EXCHANGE, REPORT_DATE, QUANTITY, COST_BASE, POSITION_VALUE, CURRENCY) 6 | VALUES 7 | ('ABC000123', 'SAFE', 'SAFEHOLD INC', 'NYSE', '2022-04-23', 100, 4015.00000, 4389.50000, 'USD') 8 | , ('ABC000123', 'STAR', 'ISTAR INC', 'NYSE', '2022-04-23', 200, 3125.00000, 2950.50000, 'USD'); 9 | 10 | SELECT 1 11 | limit 100 -------------------------------------------------------------------------------- /Chapter_14/dbt/macros/delivery/self_completing_dimension.sql: -------------------------------------------------------------------------------- 1 | {%- macro self_completing_dimension( 2 | dim_rel, 3 | dim_key_column, 4 | dim_default_key_value = '-1', 5 | rel_columns_to_exclude = [], 6 | 7 | fact_defs = [] 8 | ) -%} 9 | /* ** Usage notes ** 10 | * - The primary key has to be the first field in the underlying reference for the dimension 11 | */ 12 | 13 | {% do rel_columns_to_exclude.append(dim_key_column) -%} 14 | 15 | WITH 16 | dim_base as ( 17 | SELECT 18 | {{ dim_key_column }} 19 | , d.* EXCLUDE( {{ rel_columns_to_exclude | join(', ') }} ) 20 | FROM {{ dim_rel }} as d 21 | ), 22 | 23 | fact_key_list as ( 24 | {% if fact_defs|length > 0 %} -- If a FACT reference is passed, then check for orphans and add them in the dimension 25 | 26 | {%- for fact_model_key in fact_defs %} 27 | select distinct {{fact_model_key['key']}} as FOREIGN_KEY 28 | FROM {{ ref(fact_model_key['model']) }} 29 | WHERE {{fact_model_key['key']}} is not null 30 | {% if not loop.last %} union {% endif %} 31 | {%- endfor -%} 32 | 33 | {%- else %} -- If NO FACT reference is passed, the list of fact keys is just empty. 34 | select null as FOREIGN_KEY WHERE false 35 | {%- endif%} 36 | ), 37 | missing_keys as ( 38 | SELECT fkl.FOREIGN_KEY 39 | from fact_key_list fkl 40 | left outer join dim_base on dim_base.{{dim_key_column}} = fkl.FOREIGN_KEY 41 | where dim_base.{{dim_key_column}} is null 42 | ), 43 | default_record as ( 44 | SELECT * 45 | FROM dim_base 46 | WHERE {{dim_key_column}} = '{{dim_default_key_value}}' 47 | LIMIT 1 48 | ), 49 | dim_missing_entries as ( 50 | SELECT 51 | mk.FOREIGN_KEY, 52 | dr.* EXCLUDE( {{ dim_key_column }} ) 53 | FROM missing_keys as mk 54 | join default_record dr 55 | ), 56 | 57 | dim as ( 58 | SELECT * FROM dim_base 59 | UNION ALL 60 | SELECT * FROM dim_missing_entries 61 | ) 62 | 63 | SELECT * FROM dim 64 | 65 | {% endmacro %} 66 | -------------------------------------------------------------------------------- /Chapter_14/dbt/macros/migrations/14_10_v1__run_migrations.sql: -------------------------------------------------------------------------------- 1 | -- Adding a migration macro: 2 | -- {#% do run_query(V001_drop_XXX(database, schema_prefix)) %#} 3 | -- {#% do log("V001_drop_XXX run with database = " ~ database ~ ", schema_prefix = " ~ schema_prefix, info=True) %#} 4 | -- !! Remove the # from the above lines !! 5 | 6 | {% macro run_migrations( 7 | database = target.database, 8 | schema_prefix = target.schema 9 | ) -%} 10 | 11 | {% do log("Running V003_drop_table migration with database = " 12 | ~ database ~ ", schema_prefix = " ~ schema_prefix, info=True) %} 13 | {% do run_query(V003_drop_table(database, schema_prefix)) %} 14 | 15 | 16 | {%- endmacro %} 17 | -- How to report there are no migrations to run 18 | -- {#% do log("No migrations to run.", info=True) %#} 19 | -------------------------------------------------------------------------------- /Chapter_14/dbt/macros/migrations/14_10_v2__run_migrations.sql: -------------------------------------------------------------------------------- 1 | /** USAGE: 2 | # -- Adding a migration macro: 3 | # {#% do run_migration('V003_drop_table', database, schema_prefix) %#} 4 | # 5 | # -- How to report there are no migrations to run 6 | # {#% do log("No migrations to run.", info=True) %#} 7 | # 8 | # !! Remove the # from the above lines to uncomment 9 | # !! Update the string with the macro name!! 10 | */ 11 | 12 | {% macro run_migrations( 13 | database = target.database, 14 | schema_prefix = target.schema 15 | ) -%} 16 | 17 | {% do run_migration('V003_drop_table', database, schema_prefix) %} 18 | 19 | {%- endmacro %} 20 | 21 | 22 | /** 23 | * == Helper macro == 24 | * It that takes the name of the macro to be run, db and schema and runs it with logs. 25 | * It uses the context to get the function object from its name 26 | */ 27 | {% macro run_migration(migration_name, database, schema_prefix) %} 28 | {% if execute %} 29 | {% do log("Running " ~ migration_name ~ " migration with database = " 30 | ~ database ~ ", schema_prefix = " ~ schema_prefix, info=True) %} 31 | 32 | {% set migration_macro = context.get(migration_name, none) %} 33 | {% do run_query(migration_macro(database, schema_prefix)) if migration_macro 34 | else log("!! Macro " ~ migration_name ~ " not found. Skipping call.", info=True) %} 35 | {% endif %} 36 | {% endmacro %} -------------------------------------------------------------------------------- /Chapter_14/dbt/macros/migrations/14_11_v1__V003_drop_table_with_old_name.sql: -------------------------------------------------------------------------------- 1 | {% macro V003_drop_table( 2 | database = target.database, 3 | schema_prefix = target.schema 4 | ) -%} 5 | 6 | DROP TABLE IF EXISTS {{database}}.{{schema_prefix}}_REFINED.REF_ABC_BANK_SECURITY_INFO ; 7 | 8 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_14/dbt/macros/migrations/ARCHIVE/14_08_v1__V001_EXAMPLE_drop_table.sql: -------------------------------------------------------------------------------- 1 | {% macro V001_drop_example_table( 2 | database = target.database, 3 | schema_prefix = target.schema 4 | ) -%} 5 | 6 | DROP TABLE IF EXISTS {{database}}.{{schema_prefix}}_STAGING.TABLE_XXX ; 7 | 8 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_14/dbt/macros/migrations/ARCHIVE/14_09_v1__V002_EXAMPLE_drop_column.sql: -------------------------------------------------------------------------------- 1 | {% macro V003_drop_MD_column_in_customer() -%} 2 | 3 | {%- set model = ref('REF_GROUP_CUSTOMER') %} 4 | {%- set col = 'MD_LOAD_TS_UTC' %} 5 | 6 | {%- if coulmn_exists(model, col) %} 7 | ALTER TABLE {{ model }} 8 | DROP COLUMN {{ col }}; 9 | {%- else %} 10 | SELECT 1; 11 | {%- endif %} 12 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_14/dbt/models/14_01_v1__staging.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | models: 4 | 5 | - name: STG_ABC_BANK_POSITION 6 | tests: 7 | - dbt_utils.expression_is_true: 8 | expression: " YEAR(REPORT_DATE) >= 2000 " 9 | 10 | - name: HIST_ABC_BANK_POSITION 11 | tests: 12 | - dbt_utils.unique_combination_of_columns: 13 | combination_of_columns: 14 | - POSITION_HKEY 15 | - LOAD_TS_UTC 16 | columns: 17 | - name: POSITION_HKEY 18 | tests: 19 | - no_hash_collisions: 20 | hashed_fields: ACCOUNT_CODE, SECURITY_CODE 21 | - name: POSITION_HDIFF 22 | tests: 23 | - no_hash_collisions: 24 | hashed_fields: "{{ as_sql_list( 25 | [ 'ACCOUNT_CODE', 'SECURITY_CODE', 26 | 'SECURITY_NAME', 'EXCHANGE_CODE', 'REPORT_DATE', 27 | 'QUANTITY', 'COST_BASE', 'POSITION_VALUE', 'CURRENCY_CODE' 28 | ] ) }}" 29 | 30 | - name: HIST_ABC_BANK_SECURITY_INFO 31 | tests: 32 | - dbt_utils.unique_combination_of_columns: 33 | combination_of_columns: 34 | - SECURITY_HKEY 35 | - LOAD_TS_UTC 36 | columns: 37 | - name: SECURITY_HKEY 38 | tests: 39 | - no_hash_collisions: 40 | hashed_fields: SECURITY_CODE 41 | - name: SECURITY_HDIFF 42 | tests: 43 | - no_hash_collisions: 44 | hashed_fields: "{{ as_sql_list( 45 | [ 'SECURITY_CODE', 'SECURITY_NAME', 'SECTOR_NAME', 46 | 'INDUSTRY_NAME', 'COUNTRY_CODE', 'EXCHANGE_CODE' 47 | ] ) }}" 48 | -------------------------------------------------------------------------------- /Chapter_14/dbt/models/14_02_v1__REF_POSITION_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | current_from_history as ( 4 | {{ current_from_history( 5 | history_rel = ref('HIST_ABC_BANK_POSITION'), 6 | key_column = 'POSITION_HKEY', 7 | ) }} 8 | ) 9 | 10 | SELECT 11 | * 12 | , POSITION_VALUE - COST_BASE as UNREALIZED_PROFIT 13 | , ROUND(UNREALIZED_PROFIT / COST_BASE, 5)*100 as UNREALIZED_PROFIT_PCT 14 | FROM current_from_history 15 | -------------------------------------------------------------------------------- /Chapter_14/dbt/models/14_02_v2__REF_POSITION_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | position as ( 4 | {{ current_from_history( 5 | history_rel = ref('HIST_ABC_BANK_POSITION'), 6 | key_column = 'POSITION_HKEY', 7 | ) }} 8 | ) 9 | , security as ( 10 | SELECT * FROM {{ ref('REF_SECURITY_INFO_ABC_BANK') }} 11 | ) 12 | 13 | SELECT 14 | p.* exclude (SECURITY_CODE) 15 | , coalesce(s.SECURITY_CODE, '-1') as SECURITY_CODE 16 | , POSITION_VALUE - COST_BASE as UNREALIZED_PROFIT 17 | , ROUND(UNREALIZED_PROFIT / COST_BASE, 5)*100 as UNREALIZED_PROFIT_PCT 18 | FROM position as p 19 | LEFT OUTER JOIN security as s 20 | ON(s.SECURITY_CODE = p.SECURITY_CODE) 21 | -------------------------------------------------------------------------------- /Chapter_14/dbt/models/14_03_v1__REF_SECURITY_INFO_ABC_BANK.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | current_from_history as ( 4 | {{ current_from_history( 5 | history_rel = ref('HIST_ABC_BANK_SECURITY_INFO'), 6 | key_column = 'SECURITY_HKEY', 7 | ) }} 8 | ) 9 | 10 | SELECT * 11 | FROM current_from_history 12 | -------------------------------------------------------------------------------- /Chapter_14/dbt/models/14_04_v1__DIM_SECURITY.sql: -------------------------------------------------------------------------------- 1 | SELECT * FROM {{ ref('REF_SECURITY_INFO_ABC_BANK') }} -------------------------------------------------------------------------------- /Chapter_14/dbt/models/14_08_v1__HIST_ABC_BANK_POSITION_WITH_CLOSING.sql: -------------------------------------------------------------------------------- 1 | {{ config(materialized='incremental') }} 2 | 3 | WITH 4 | stg_input as ( 5 | SELECT 6 | i.* EXCLUDE (REPORT_DATE, QUANTITY, COST_BASE, POSITION_VALUE, LOAD_TS_UTC) 7 | , REPORT_DATE 8 | , QUANTITY 9 | , COST_BASE 10 | , POSITION_VALUE 11 | , LOAD_TS_UTC 12 | , false as CLOSED 13 | FROM {{ ref('STG_ABC_BANK_POSITION') }} as i 14 | ) 15 | 16 | {% if is_incremental() %}-- in an incremental run and the dest table already exists 17 | , current_from_history as ( 18 | {{ current_from_history( 19 | history_rel = this, 20 | key_column = 'POSITION_HKEY', 21 | ) }} 22 | ), 23 | 24 | load_from_input as ( 25 | SELECT 26 | i.* 27 | FROM stg_input as i 28 | LEFT OUTER JOIN current_from_history curr ON (not curr.closed and i.POSITION_HDIFF = curr.POSITION_HDIFF) 29 | WHERE curr.POSITION_HDIFF is null 30 | ), 31 | closed_from_hist as ( 32 | SELECT 33 | curr.* EXCLUDE (REPORT_DATE, QUANTITY, COST_BASE, POSITION_VALUE, LOAD_TS_UTC, CLOSED) 34 | , (SELECT MAX(REPORT_DATE) FROM stg_input) as REPORT_DATE 35 | , 0 as QUANTITY 36 | , 0 as COST_BASE 37 | , 0 as POSITION_VALUE 38 | , '{{ run_started_at }}' as LOAD_TS_UTC 39 | , true as CLOSED 40 | FROM current_from_history curr 41 | LEFT OUTER JOIN stg_input as i ON (i.POSITION_HKEY = curr.POSITION_HKEY) 42 | WHERE not curr.closed and i.POSITION_HKEY is null 43 | ), 44 | 45 | changes_to_store as ( 46 | SELECT * FROM load_from_input 47 | UNION ALL 48 | SELECT * FROM closed_from_hist 49 | ) 50 | {%- else %}-- not an incremental run (like a full-refresh) or the dest table does not yet exists 51 | , changes_to_store as ( 52 | SELECT * 53 | FROM stg_input 54 | ) 55 | {%- endif %} 56 | 57 | SELECT * FROM changes_to_store 58 | -------------------------------------------------------------------------------- /Chapter_14/dbt/snapshots/14_05_v1__snapshots.yml: -------------------------------------------------------------------------------- 1 | version: 2 2 | 3 | snapshots: 4 | 5 | - name: SNSH_ABC_BANK_POSITION 6 | # columns: 7 | # - name: POSITION_HKEY 8 | # tests: 9 | # - no_hash_collisions: 10 | # hashed_fields: ACCOUNT_CODE, SECURITY_CODE 11 | # - name: POSITION_HDIFF 12 | # tests: 13 | # - no_hash_collisions: 14 | # hashed_fields: "{{ as_sql_list( 15 | # [ 'ACCOUNT_CODE', 'SECURITY_CODE', 16 | # 'SECURITY_NAME', 'EXCHANGE_CODE', 'REPORT_DATE', 17 | # 'QUANTITY', 'COST_BASE', 'POSITION_VALUE', 'CURRENCY_CODE' 18 | # ] ) }}" 19 | 20 | - name: SNSH_ABC_BANK_SECURITY_INFO 21 | # columns: 22 | # - name: SECURITY_HKEY 23 | # tests: 24 | # - no_hash_collisions: 25 | # hashed_fields: SECURITY_CODE 26 | # - name: SECURITY_HDIFF 27 | # tests: 28 | # - no_hash_collisions: 29 | # hashed_fields: "{{ as_sql_list( 30 | # [ 'SECURITY_CODE', 'SECURITY_NAME', 'SECTOR_NAME', 31 | # 'INDUSTRY_NAME', 'COUNTRY_CODE', 'EXCHANGE_CODE' 32 | # ] ) }}" 33 | -------------------------------------------------------------------------------- /Chapter_14/dbt/snapshots/14_06_v1__SNSH_ABC_BANK_POSITION.sql: -------------------------------------------------------------------------------- 1 | {% snapshot SNSH_ABC_BANK_POSITION %} 2 | 3 | {{ config(enabled=false) }} 4 | 5 | {{ 6 | config( 7 | unique_key= 'POSITION_HKEY', 8 | 9 | strategy='check', 10 | check_cols=['POSITION_HDIFF'], 11 | invalidate_hard_deletes=True, 12 | ) 13 | }} 14 | 15 | select * from {{ ref('STG_ABC_BANK_POSITION') }} 16 | 17 | {% endsnapshot %} -------------------------------------------------------------------------------- /Chapter_14/dbt/snapshots/14_07_v1__SNSH_ABC_BANK_SECURITY_INFO.sql: -------------------------------------------------------------------------------- 1 | {% snapshot SNSH_ABC_BANK_SECURITY_INFO %} 2 | 3 | {{ config(enabled=false) }} 4 | 5 | {{ 6 | config( 7 | unique_key= 'SECURITY_HKEY', 8 | 9 | strategy='check', 10 | check_cols=['SECURITY_HDIFF'], 11 | ) 12 | }} 13 | 14 | select * from {{ ref('STG_ABC_BANK_SECURITY_INFO') }} 15 | 16 | {% endsnapshot %} -------------------------------------------------------------------------------- /Chapter_15/dbt/analysis/15_01_v1__infer_schema_snippets.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * ** List the files in a stage ** 3 | */ 4 | list '@../path/folder/.../' 5 | PATTERN = '.*[.]parquet'; 6 | 7 | /* 8 | INFER_SCHEMA( 9 | LOCATION => '@mystage/path/folder/' 10 | , FILE_FORMAT => 'my_parquet_format' 11 | , FILES => '' [, ''] 12 | ) 13 | */ 14 | 15 | select * 16 | --select expression as sql_select 17 | --select column_name || ' ' || type || ' ,' as sql_create_table 18 | --SELECT COLUMN_NAME || ' ' || TYPE || ' as (' || EXPRESSION|| ') ,' as sql_ext_table 19 | --SELECT GENERATE_COLUMN_DESCRIPTION(ARRAY_AGG(OBJECT_CONSTRUCT(*)), 'table') AS COLUMNS 20 | from table( 21 | INFER_SCHEMA( 22 | LOCATION => '@../path/folder/.../' 23 | , FILE_FORMAT => '..' 24 | , FILES => '' -- , '' 25 | -- , IGNORE_CASE => TRUE 26 | ) 27 | ); 28 | -------------------------------------------------------------------------------- /Chapter_15/dbt/analysis/15_02_v1__external_table_snippets.sql: -------------------------------------------------------------------------------- 1 | 2 | /* ** Create from "manual" COLUMN definition ** */ 3 | CREATE EXTERNAL TABLE my_ext_table 4 | ( 5 | file_part as () 6 | col1 varchar AS (value:col1::varchar) 7 | ) 8 | PARTITION BY (file_part) 9 | LOCATION=@mystage/daily/ -- @stage/path 10 | FILE_FORMAT = my_file_format 11 | AUTO_REFRESH = FALSE; 12 | 13 | /* ** Create from "automated" COLUMN definition ** */ 14 | CREATE EXTERNAL TABLE my_ext_table 15 | USING TEMPLATE ( 16 | SELECT ARRAY_AGG(OBJECT_CONSTRUCT(*)) 17 | FROM TABLE( 18 | INFER_SCHEMA( 19 | LOCATION=>'@mystage', 20 | FILE_FORMAT=>'my_ file _format' 21 | ) 22 | ) 23 | ) 24 | PARTITION BY (file_part) 25 | LOCATION=@mystage/daily/ -- @stage/path 26 | FILE_FORMAT = my_file_format 27 | AUTO_REFRESH = FALSE; 28 | 29 | /* ** Create Ext Table from Delta Lake file format ** */ 30 | CREATE EXTERNAL TABLE my_ext_table ( 31 | -- table definition as above 32 | ) 33 | TABLE_FORMAT = DELTA; 34 | 35 | 36 | -------------------------------------------------------------------------------- /Chapter_15/dbt/analysis/15_15_v1__schema_evolution_snippets.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * Single model joining the multiple sources from schema evolution. 3 | * As each source could provide more than one version for each key 4 | * we use a second time the current_from_history macro to keep only the latest. 5 | */ 6 | 7 | WITH 8 | current_from_old_histories as ( 9 | SELECT * FROM {{ ref('REF_XXX_old_curr') }} 10 | ), 11 | current_from_history as ( 12 | {{ current_from_history( 13 | history_rel = ref(' HIST_XXX_Vn'), 14 | key_column = 'XXX_HKEY' 15 | ) }} 16 | ), 17 | all_current as ( 18 | SELECT * FROM current_from_history 19 | UNION ALL 20 | SELECT * FROM current_from_old_histories 21 | ) 22 | 23 | {{ current_from_history( 24 | history_rel ='all_current', 25 | key_column = 'XXX_HKEY' 26 | ) }} 27 | -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_code/land_XXX/15_03_v1__setup_XXX.sql: -------------------------------------------------------------------------------- 1 | {% macro run_setup_XXX() %} 2 | {{ log('** Setting up the LANDING / EXTERNAL tables schema, FF and STAGE for XXX system **', true) }} 3 | {% do run_query(setup_XXX_sql()) %} 4 | {%- endmacro %} 5 | 6 | {% macro setup_XXX_sql() %} 7 | {{ create_XXX_schema_sql() }} 8 | {{ create_XXX__ff_sql() }} 9 | {{ create_XXX__stage_sql() }} 10 | {%- endmacro %} 11 | 12 | /* DEFINE Names */ 13 | {% macro get_XXX_db_name() %} 14 | {% do return( target.database ) %} 15 | {%- endmacro %} 16 | 17 | {% macro get_XXX_schema_name() %} 18 | {% do return( 'LAND_XXX' ) %} 19 | {%- endmacro %} 20 | 21 | {% macro get_XXX_ff_name() %} -- return fully qualified name 22 | {% do return( get_XXX_db_name() ~ '.' ~ get_XXX_schema_name() ~ '.XXX_CSV__FF' ) %} 23 | {%- endmacro %} 24 | 25 | {% macro get_XXX_stage_name() %} -- return fully qualified name 26 | {% do return( get_XXX_db_name() ~ '.' ~ get_XXX_schema_name() ~ '.XXX_CSV_STAGE' ) %} 27 | {%- endmacro %} 28 | 29 | 30 | 31 | {% macro create_XXX_schema_sql() %} 32 | CREATE SCHEMA IF NOT EXISTS {{ get_XXX_db_name() }}.{{ get_XXX_schema_name() }} 33 | COMMENT = 'The Landing Schema for XXX data.'; 34 | {%- endmacro %} 35 | 36 | 37 | 38 | {% macro create_XXX__ff_sql() %} 39 | 40 | CREATE FILE FORMAT IF NOT EXISTS {{ get_XXX_ff_name() }} 41 | TYPE = 'csv' 42 | field_delimiter = ',' 43 | SKIP_HEADER = 1 44 | -- ENCODING = 'ISO-8859-1' -- For nordic languages 45 | FIELD_OPTIONALLY_ENCLOSED_BY = '"' 46 | ; 47 | 48 | {# --If you make only one for all environments you need to authorize all roles 49 | {% for env in var('environments') %} 50 | GRANT USAGE ON FILE FORMAT {{ get_XXX_ff_name() }} TO ROLE {{ var('prj_name') }}_{{env}}_RW; 51 | {%- endfor %} 52 | #} 53 | 54 | {%- endmacro %} 55 | 56 | 57 | {% macro create_XXX__stage_sql() %} 58 | 59 | CREATE STAGE IF NOT EXISTS {{ get_XXX_stage_name() }} 60 | storage_integration = STORAGE_INTEGRATION_NAME 61 | url = 'azure://stg_account.blob.core.windows.net/XYZ-container/XXX/' 62 | file_format = {{ get_XXX_ff_name() }}; 63 | 64 | {# --If you make only one for all environments you need to authorize all roles 65 | {% for env in var('environments') %} 66 | GRANT USAGE ON STAGE {{ get_XXX_stage_name() }} TO ROLE {{ var('prj_name') }}_{{env}}_RW; 67 | {%- endfor %} 68 | #} 69 | 70 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_code/land_XXX/15_04_v1__table_YYY.sql: -------------------------------------------------------------------------------- 1 | {% macro load_YYYYYY( 2 | db_name = get_XXX_ingestion_db_name(), 3 | schema_name = get_XXX_ingestion_schema_name(), 4 | stage_name = get_XXX_ingestion_stage_name(), 5 | format_name = None, 6 | table_name = 'YYYYYY', 7 | pattern = '.*YYYYYY.csv', 8 | field_count = 12 9 | ) %} 10 | 11 | {% set full_table_name = db_name ~ '.' ~ schema_name ~ '.' ~ table_name %} 12 | 13 | {{ log('Creating table ' ~ full_table_name ~ ' if not exists', true) }} 14 | {% do run_query(XXX_YYYYYY__create_table_sql(full_table_name)) %} 15 | {{ log('Created table ' ~ full_table_name ~ ' if not exists', true) }} 16 | 17 | {{ log('Ingesting data in table ' ~ full_table_name ~ '.', true) }} 18 | {% do run_query(ingest_into_landing_sql( 19 | full_table_name, 20 | field_count = field_count, 21 | file_pattern = pattern, 22 | full_stage_name = stage_name, 23 | full_format_name = format_name 24 | ) ) %} 25 | {{ log('Ingested data in table ' ~ full_table_name ~ '.', true) }} 26 | 27 | /* Add a cleanup step of the LT when ingesting (big) full exports 28 | A simple strategy is to keep the last N ingestion timestamps. 29 | */ 30 | 31 | {%- endmacro %} 32 | 33 | {% macro XXX_YYYYYY__create_table_sql(full_table_name) %} 34 | 35 | -- ** Create table if not exists 36 | CREATE TRANSIENT TABLE {{ full_table_name }} IF NOT EXISTS 37 | ( 38 | -- Add declaration for table columns 39 | -- column type [[NOT] NULL], 40 | YYY_CODE string NOT NULL, 41 | YYY_NAME string NULL, 42 | 43 | -- metadata 44 | FROM_FILE string, 45 | FILE_ROW_NUMBER integer, 46 | INGESTION_TS_UTC TIMESTAMP_NTZ(9) 47 | ) 48 | COMMENT = '...'; 49 | 50 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_code/land_XXX/15_06_v1__table_ZZZ.sql: -------------------------------------------------------------------------------- 1 | {% macro load_ZZZ( 2 | db_name = get_XXX_ingestion_db_name(), 3 | schema_name = get_XXX_ingestion_schema_name(), 4 | stage_name = get_XXX_ingestion_stage_name(), 5 | format_name = None, 6 | table_name = 'ZZZ', 7 | pattern = '.*ZZZ[.]parquet' 8 | ) %} 9 | 10 | {% set full_table_name = db_name ~ '.' ~ schema_name ~ '.' ~ table_name %} 11 | 12 | {{ log('Creating table ' ~ full_table_name ~ ' if not exists', true) }} 13 | {% do run_query(X_Z__create_table_sql(full_table_name)) %} 14 | {{ log('Created table ' ~ full_table_name ~ ' if not exists', true) }} 15 | 16 | {% set field_expressions %} 17 | $1 as src_data, 18 | $1:ZZZ_CODE::string as ZZZ_CODE, 19 | $1:ZZZ_NAME::string as ZZZ_NAME, 20 | $1:ZZZ_VALUE::double as ZZZ_VALUE 21 | {% endset %} 22 | 23 | {{ log('Ingesting data in table ' ~ full_table_name ~ '.', true) }} 24 | {% do run_query(ingest_semi_structured_into_landing_sql( 25 | full_table_name, 26 | field_expressions, 27 | file_pattern = pattern, 28 | full_stage_name = stage_name, 29 | full_format_name = format_name 30 | ) ) %} 31 | {{ log('Ingested data in table ' ~ full_table_name ~ '.', true) }} 32 | 33 | /* Add a cleanup step of the LT when ingesting (big) full exports 34 | * A simple strategy is to keep the last N ingestion timestamps. 35 | */ 36 | 37 | {%- endmacro %} 38 | 39 | {% macro X_Z__create_table_sql(full_table_name) %} 40 | 41 | -- ** Create table if not exists 42 | CREATE TRANSIENT TABLE {{ full_table_name }} IF NOT EXISTS 43 | ( 44 | -- Add declaration for table columns 45 | -- column type [[NOT] NULL], 46 | SRC_DATA variant, 47 | ZZZ_CODE string NOT NULL, 48 | ZZZ_NAME string, 49 | ZZZ_VALUE double, 50 | 51 | -- metadata 52 | FROM_FILE string, 53 | FILE_ROW_NUMBER integer, 54 | INGESTION_TS_UTC TIMESTAMP_NTZ(9) 55 | ) 56 | COMMENT = '...'; 57 | 58 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_code/land_XXX/15_08_v1__load_XXX_landing_tables.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * This macro runs all the inividual macros to load the landing tables for the XXX source system. 3 | */ 4 | {% macro load_XXX_landing_tables() %} 5 | {{ log('*** Load the landing tables for XXX system ***', true) }} 6 | 7 | {{ log('** Setting up the LANDING / EXTERNAL tables schema, FF and STAGE for XXX system **', true) }} 8 | {% do run_query(setup_XXX_sql()) %} 9 | 10 | {{ log('* load_YYYYYY *', true) }} 11 | {% do load_YYYYYY() %} 12 | 13 | 14 | {{ log('*** DONE Loading the landing tables for XXX system ***', true) }} 15 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_lib/15_05_v1__ingest_into_landing_sql.sql: -------------------------------------------------------------------------------- 1 | {% macro ingest_into_landing_sql( 2 | full_table_name, 3 | field_count, 4 | file_pattern, 5 | full_stage_name, 6 | full_format_name 7 | ) %} 8 | BEGIN TRANSACTION; 9 | 10 | COPY INTO {{ full_table_name }} 11 | FROM ( 12 | SELECT 13 | {% for i in range(1, field_count+1) %}${{i}},{% endfor %} 14 | 15 | METADATA$FILENAME as FROM_FILE, 16 | METADATA$FILE_ROW_NUMBER as FILE_ROW_NUMBER, 17 | '{{ run_started_at }}' as INGESTION_TS_UTC 18 | 19 | FROM @{{ full_stage_name }}/ 20 | ) 21 | PATTERN = '{{ file_pattern }}' 22 | {%- if full_format_name %} 23 | , FILE_FORMAT = (FORMAT_NAME = '{{ full_format_name }}') 24 | {%- endif %} 25 | ; 26 | 27 | COMMIT; 28 | 29 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_lib/15_07_v1__ingest_semi_structured_into_landing_sql.sql: -------------------------------------------------------------------------------- 1 | {% macro ingest_semi_structured_into_landing_sql( 2 | full_table_name, 3 | field_expressions, 4 | file_pattern, 5 | full_stage_name, 6 | full_format_name 7 | ) %} 8 | BEGIN TRANSACTION; 9 | 10 | COPY INTO {{ full_table_name }} 11 | FROM ( 12 | SELECT 13 | {{ field_expressions }}, 14 | 15 | METADATA$FILENAME as FROM_FILE, 16 | METADATA$FILE_ROW_NUMBER as FILE_ROW_NUMBER, 17 | '{{ run_started_at }}' as INGESTION_TS_UTC 18 | 19 | FROM @{{ full_stage_name }}/ 20 | ) 21 | PATTERN = '{{ file_pattern }}' 22 | {%- if full_format_name %} 23 | , FILE_FORMAT = (FORMAT_NAME = '{{ full_format_name }}') 24 | {%- endif %} 25 | ; 26 | 27 | COMMIT; 28 | 29 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_lib/15_09_v1__get_file_pattern.sql: -------------------------------------------------------------------------------- 1 | {%- macro get_file_pattern( 2 | table_name, 3 | num_days = 5, 4 | last_date = None, 5 | file_path_prefix = 'root-folder/', 6 | file_path_suffix = '[.]gz' 7 | ) -%} 8 | 9 | {%- if last_date %} 10 | {%- set base_date = modules.datetime.date.fromisoformat(last_date) %} 11 | {%- else %} 12 | {%- set base_date = modules.datetime.date.today() %} 13 | {% endif -%} 14 | 15 | {%- set dates = [] -%} 16 | {%- for d in range(num_days) -%} 17 | {%- set time_delta = modules.datetime.timedelta(days=d) %} 18 | {%- set _ = dates.append( (base_date-time_delta).strftime('%Y/%m/%d') ) -%} 19 | {% endfor -%} 20 | 21 | {{file_path_prefix}}{{table_name}}/({{dates|join('|')}})/.*{{table_name}}.*{{file_path_suffix}} 22 | 23 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/ingestion_lib/15_09_v2__get_file_pattern.sql: -------------------------------------------------------------------------------- 1 | {%- macro get_file_pattern( 2 | table_name, 3 | num_days = 5, 4 | last_date = None, 5 | file_path_prefix = 'root-folder/', 6 | file_path_suffix = '[.]gz' 7 | ) -%} 8 | 9 | {% if num_days and not var('load_all_dates', false) %} 10 | {%- if last_date %} 11 | {%- set base_date = modules.datetime.date.fromisoformat(last_date) %} 12 | {%- else %} 13 | {%- set base_date = modules.datetime.date.today() %} 14 | {% endif -%} 15 | 16 | {%- set dates = [] -%} 17 | {%- for d in range(num_days) -%} 18 | {%- set time_delta = modules.datetime.timedelta(days=d) %} 19 | {%- set _ = dates.append( (base_date-time_delta).strftime('%Y/%m/%d') ) -%} 20 | {% endfor -%} 21 | 22 | {% do return(file_path_prefix ~ table_name ~ '/(' ~ dates|join('|') ~ ')/.*' ~ table_name ~ '.*' ~ file_path_suffix) %} 23 | {% else -%} 24 | {% do return(file_path_prefix ~ table_name ~ '/.*' ~ table_name ~ '.*' ~ file_path_suffix) %} 25 | {% endif -%} 26 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/storage/15_10_v1__save_history_with_deletion.sql: -------------------------------------------------------------------------------- 1 | {% macro save_history_with_deletion( 2 | input_rel, 3 | key_column, 4 | diff_column, 5 | load_ts_column = 'LOAD_TS_UTC' 6 | ) -%} 7 | 8 | {{ config(materialized='incremental') }} 9 | 10 | WITH 11 | 12 | {% if is_incremental() %}-- in an incremental run and the dest table already exists 13 | current_from_history as ( 14 | {{- current_from_history( 15 | history_rel = this, 16 | key_column = key_column, 17 | load_ts_column = load_ts_column, 18 | ) }} 19 | ), 20 | 21 | load_from_input as ( 22 | SELECT 23 | i.* EXCLUDE ({{load_ts_column}}) 24 | , i.{{load_ts_column}} 25 | , false as deleted 26 | FROM {{ input_rel }} as i 27 | LEFT OUTER JOIN current_from_history curr ON (not curr.deleted and i.{{diff_column}} = curr.{{diff_column}}) 28 | WHERE curr.{{diff_column}} is null 29 | ), 30 | deleted_from_hist as ( 31 | SELECT 32 | curr.* EXCLUDE (deleted, {{load_ts_column}}) 33 | , '{{ run_started_at }}' as {{load_ts_column}} 34 | , true as deleted 35 | FROM current_from_history curr 36 | LEFT OUTER JOIN {{ input_rel }} as i ON (i.{{key_column}} = curr.{{key_column}}) 37 | WHERE not curr.deleted and i.{{key_column}} is null 38 | ), 39 | 40 | changes_to_store as ( 41 | SELECT * FROM load_from_input 42 | UNION ALL 43 | SELECT * FROM deleted_from_hist 44 | ) 45 | {%- else %}-- not an incremental run (like a full-refresh) or the dest table does not yet exists 46 | changes_to_store as ( 47 | SELECT 48 | i.* EXCLUDE ({{load_ts_column}}) 49 | , {{load_ts_column}} 50 | , false as deleted 51 | FROM {{ input_rel }} as i 52 | ) 53 | {%- endif %} 54 | 55 | SELECT * FROM changes_to_store 56 | 57 | {% endmacro %} 58 | -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/storage/15_11_v1__current_from_history.sql: -------------------------------------------------------------------------------- 1 | {% macro current_from_history( 2 | history_rel, 3 | key_column, 4 | selection_expr = '*', 5 | load_ts_column = 'LOAD_TS_UTC', 6 | history_filter_expr = 'true', 7 | qualify_function = 'row_number' 8 | ) -%} 9 | 10 | SELECT {{selection_expr}} 11 | FROM {{history_rel}} 12 | WHERE {{history_filter_expr}} 13 | QUALIFY {{qualify_function}}() OVER( PARTITION BY {{key_column}} ORDER BY {{load_ts_column}} desc) = 1 14 | 15 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/storage/15_12_v1__save_history_with_deletion_from_list.sql: -------------------------------------------------------------------------------- 1 | /** 2 | * Important usage notes: 3 | * 1. When a Key is marked deleted in the HIST table, it will be added again as not deleted, if it's presented in the STG input. 4 | * 2. When a Key is not marked deleted in the HIST table, it will be added again marked deleted, if it's presented in the DEL input. 5 | * 3. The combined result of #1 and #2 is that if a key is present in both STG and DEL input, the result will depend on its state in HIST. 6 | * If the key is delete, it will be undeleted, while if it was not delete, it will be deleted. 7 | * 4. A priority must be estabilished between the two inputs, if we want to remove this alternance. 8 | * Giving priority to the STG input, it would mean that keys appearing in STG would be removed from the deletion list. 9 | * Giving priority to the DEL input, it would mean that keys appearing in DEL list would be removed from the STG input. 10 | * The above rules can be implemented in the STG model being fed to the macro. 11 | */ 12 | {% macro save_history_with_deletion_from_list( 13 | input_rel, 14 | key_column, 15 | diff_column, 16 | 17 | del_rel, 18 | del_key_column, 19 | 20 | load_ts_column = 'LOAD_TS_UTC', 21 | input_filter_expr = 'true', 22 | high_watermark_column = none, 23 | high_watermark_test = '>=', 24 | order_by_expr = none 25 | ) -%} 26 | 27 | {{ config(materialized='incremental') }} 28 | 29 | WITH 30 | 31 | {% if is_incremental() %}-- in an incremental run and the dest table already exists 32 | current_from_history as ( 33 | {{- current_from_history( 34 | history_rel = this, 35 | key_column = key_column, 36 | load_ts_column = load_ts_column, 37 | ) }} 38 | ), 39 | 40 | load_from_input as ( 41 | SELECT 42 | i.* EXCLUDE ({{load_ts_column}}) 43 | , i.{{load_ts_column}} 44 | , false as deleted 45 | FROM {{ input_rel }} as i 46 | LEFT OUTER JOIN current_from_history curr ON (not curr.deleted and i.{{diff_column}} = curr.{{diff_column}}) 47 | WHERE curr.{{diff_column}} is null 48 | and {{input_filter_expr}} 49 | {%- if high_watermark_column %} 50 | and {{high_watermark_column}} {{high_watermark_test}} (select max({{high_watermark_column}}) from {{ this }}) 51 | {%- endif %} 52 | ), 53 | delete_from_hist as ( 54 | SELECT 55 | curr.* EXCLUDE (deleted, {{load_ts_column}}) 56 | , '{{ run_started_at }}' as {{load_ts_column}} 57 | , true as deleted 58 | FROM current_from_history curr 59 | WHERE not curr.deleted 60 | and curr.{{key_column}} IN ( SELECT {{del_key_column}} FROM {{del_rel}} ) 61 | ), 62 | 63 | changes_to_store as ( 64 | SELECT * FROM load_from_input 65 | UNION ALL 66 | SELECT * FROM delete_from_hist 67 | ) 68 | {%- else %}-- not an incremental run (like a full-refresh) or the dest table does not yet exists 69 | changes_to_store as ( 70 | SELECT 71 | i.* EXCLUDE ({{load_ts_column}}) 72 | , {{load_ts_column}} 73 | , false as deleted 74 | FROM {{ input_rel }} as i 75 | WHERE {{ input_filter_expr }} 76 | ) 77 | {%- endif %} 78 | 79 | SELECT * FROM changes_to_store 80 | {%- if order_by_expr %} 81 | ORDER BY {{order_by_expr}} 82 | {%- endif %} 83 | 84 | {% endmacro %} 85 | -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/storage/15_13_v1__save_history_with_multiple_versions.sql: -------------------------------------------------------------------------------- 1 | {% macro save_history_with_multiple_versions( 2 | input_rel, 3 | key_column, 4 | diff_column, 5 | sort_expr, 6 | history_rel = this, 7 | load_ts_column = 'LOAD_TS_UTC', 8 | input_filter_expr = 'true', 9 | history_filter_expr = 'true', 10 | high_watermark_column = none, 11 | high_watermark_test = '>=' 12 | ) -%} 13 | 14 | {{- config(materialized='incremental') }} 15 | {%- if execute and not flags.FULL_REFRESH %} 16 | {% set incremental_w_external_input = (history_rel != this) %} 17 | {% endif -%} 18 | 19 | WITH 20 | {% if is_incremental() or incremental_w_external_input %} 21 | 22 | {%- set selection_expression %} 23 | {{key_column}}, {{diff_column}} 24 | , row_number() OVER( PARTITION BY {{key_column}}, {{load_ts_column}} ORDER BY {{sort_expr}}) as rn 25 | , count(*) OVER( PARTITION BY {{key_column}}, {{load_ts_column}}) as cnt 26 | {%- endset -%} 27 | 28 | current_from_history as ( 29 | {{current_from_history( 30 | history_rel = history_rel, 31 | key_column = key_column, 32 | selection_expr = selection_expression, 33 | load_ts_column = load_ts_column, 34 | history_filter_expr = history_filter_expr, 35 | qualify_function = '(rn = cnt) and rank' 36 | ) }} 37 | ), 38 | 39 | load_from_input as ( 40 | SELECT 41 | i.* 42 | , LAG(i.{{diff_column}}) OVER(PARTITION BY i.{{key_column}} ORDER BY {{sort_expr}}) as PREV_HDIFF 43 | , CASE 44 | WHEN PREV_HDIFF is null THEN COALESCE(i.{{diff_column}} != h.{{diff_column}}, true) 45 | ELSE (i.{{diff_column}} != PREV_HDIFF) 46 | END as TO_BE_STORED 47 | FROM {{input_rel}} as i 48 | LEFT OUTER JOIN current_from_history as h ON h.{{key_column}} = i.{{key_column}} 49 | WHERE {{input_filter_expr}} 50 | {%- if high_watermark_column %} 51 | and {{high_watermark_column}} {{high_watermark_test}} (select max({{high_watermark_column}}) from {{ history_rel }}) 52 | {%- endif %} 53 | ) 54 | 55 | {%- else %} 56 | load_from_input as ( 57 | SELECT 58 | i.* 59 | , LAG(i.{{diff_column}}) OVER(PARTITION BY i.{{key_column}} ORDER BY {{sort_expr}}) as PREV_HDIFF 60 | , CASE 61 | WHEN PREV_HDIFF is null THEN true 62 | ELSE (i.{{diff_column}} != PREV_HDIFF) 63 | END as TO_BE_STORED 64 | FROM {{input_rel}} as i 65 | WHERE {{input_filter_expr}} 66 | ) 67 | {%- endif %} 68 | 69 | SELECT * EXCLUDE(PREV_HDIFF, TO_BE_STORED) 70 | FROM load_from_input 71 | WHERE TO_BE_STORED 72 | ORDER BY {{key_column}}, {{sort_expr}} 73 | 74 | {%- endmacro %} -------------------------------------------------------------------------------- /Chapter_15/dbt/macros/storage/15_14_v1__current_from_history_with_multiple_versions.sql: -------------------------------------------------------------------------------- 1 | {% macro current_from_history_with_multiple_versions( 2 | history_rel, 3 | key_column, 4 | sort_expr, 5 | selection_expr = '*', 6 | load_ts_column = 'LOAD_TS_UTC', 7 | history_filter_expr = 'true', 8 | qualify_function = '(rn = cnt) and rank' 9 | ) %} 10 | 11 | {%- set multiple_versions_selection_expression %} 12 | {{selection_expr}} 13 | , row_number() OVER( PARTITION BY {{key_column}}, {{load_ts_column}} ORDER BY {{sort_expr}}) as rn 14 | , count(*) OVER( PARTITION BY {{key_column}}, {{load_ts_column}}) as cnt 15 | {%- endset -%} 16 | 17 | {{current_from_history( 18 | history_rel = history_rel, 19 | key_column = key_column, 20 | selection_expr = multiple_versions_selection_expression, 21 | load_ts_column = load_ts_column, 22 | history_filter_expr = history_filter_expr, 23 | qualify_function = qualify_function 24 | ) }} 25 | 26 | {% endmacro %} -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2022 Packt 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | 2 | ### [Packt Conference : Put Generative AI to work on Oct 11-13 (Virtual)](https://packt.link/JGIEY) 3 | 4 |

[![Packt Conference](https://hub.packtpub.com/wp-content/uploads/2023/08/put-generative-ai-to-work-packt.png)](https://packt.link/JGIEY)

5 | 3 Days, 20+ AI Experts, 25+ Workshops and Power Talks 6 | 7 | Code: USD75OFF 8 | 9 | # Data Engineering with dbt - Code Samples 10 | This repository contains code samples for the book **Data Engineering with dbt** by Roberto Zagni, published by PacktPublishing. 11 | 12 | Please look up the [LICENSE](LICENSE) before using this repository. 13 | 14 | ## Organization of this Repository 15 | This is not the repository for the dbt project used as a sample in the book, even if it includes the code for that project. 16 | At the end of this readme there is a small presentation of [the sample dbt project](#the-sample-dbt-project) 17 | 18 | The files in this repo represents the **evolution of the code** as discussed in the different chapters of the book. 19 | Because of that the files are organized by book chapter. 20 | 21 | When one source file undergoes many substantial changes in a chapter we have provided multiple versions of the file to 22 | represent the multiple stages discussed in the chapter. 23 | 24 | ### Samples from the introductory chapters 25 | In the first chapters we introduce Snowflake and dbt and the samples are about snippets of code, 26 | so we have provided one file per section as often individual snippets are too tiny to justify a single file per sample. 27 | Longer samples can be in their own file. 28 | 29 | ### Code from the remaining chapters 30 | In chapter 5 we start the sample dbt project and from that point onward each file in this repo represents 31 | one version of a file in the dbt project or a sample that we have discussed even if not part of the sample project. 32 | 33 | Inside each chapter the files that represent dbt objects (models, macros and others) are under a `dbt` folder, 34 | while other files that might represent CSV files or commands to be executed in Snowflake are in separate folders. 35 | 36 | In the early phases of the sample project we have few models, so they all are under the `dbt` folder. 37 | When we have multiple types of dbt object we have placed each type of file in its sub-folder. 38 | 39 | 40 | ## The sample dbt project 41 | The book **Data Engineering with dbt** uses a sample project to describe how dbt works with a practical approach. 42 | 43 | The sample starts simple and then is evolved introducing more dbt features and software engineering best practices. 44 | 45 | The sample is not intended to be a full fledged project, but just a tool to discuss ho to approach the building 46 | of real dbt projects applying the right features and best practices. 47 | 48 | As such the sample project uses few dbt models and evolves them by introducing new dbt features 49 | and explaining the software engineering principles that guide the evolution of the models or the use of one 50 | feature instead of another. 51 | 52 | In the book we often refer to the organization of the sample project, including folder names. 53 | The layout of the sample dbt project described in the book can be seen in the following picture: 54 | 55 | ![The layout of the dbt project](dbt_project_layout.png) 56 | 57 | 58 | -------------------------------------------------------------------------------- /dbt_project_layout.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/PacktPublishing/Data-engineering-with-dbt/c0f850d045f9ab459f0f96cafc1be7bb3dadb568/dbt_project_layout.png --------------------------------------------------------------------------------