├── Chapter Code ├── Chapter01.sql ├── Chapter02.sql ├── Chapter03.sql ├── Chapter04.sql ├── Chapter05.sql ├── Chapter06.sql ├── Chapter07.sql ├── Chapter08.sql ├── Chapter09.sql ├── Chapter10.sql ├── Chapter11.sql └── Chapter12.sql ├── README.md └── Supplemental Material ├── DataVault Tutoral Reference Diagram.png ├── DataVault Tutorial Code.sql ├── Snowflake Connectors for Salesforce Analytics Studio.sql └── SnowflakeResources /Chapter Code/Chapter01.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 1: Getting Started 6 | 7 | 8 | // Page 3 - Prep Work 9 | // Set up trial account if needed, see Appendix C 10 | // Navigate to the Snowsight UI, if Classic Console is the default 11 | 12 | // Page 6 - Set your role 13 | // Set your role to SYSADMIN 14 | 15 | // Page 7 - Profile submenu 16 | // Review the Profile submenu and enroll in MFA, if desired 17 | 18 | // Page 9 - Context setting 19 | // Make sure your role is set to SYSADMIN and your warehouse to COMPUTE_WH 20 | 21 | // Page 9 - Create folder and worksheet 22 | // Create folder: Chapter 1 23 | // Create worksheet: Chapter1 Getting Started 24 | 25 | // Page 11 - Using the blue arrow button, the Run button in Snowflake 26 | SELECT CURRENT_ROLE(); 27 | SELECT CURRENT_WAREHOUSE(); 28 | 29 | // Page 12 - See what is the current database 30 | SELECT CURRENT_DATABASE(); 31 | 32 | // Page 12 - Set context for the database to be used 33 | USE DATABASE SNOWFLAKE_SAMPLE_DATA; 34 | 35 | // Page 13 - Set context for the schema to be used 36 | // Select the TPCDS_SF100TCL Schema from the menu 37 | 38 | // Page 14 - Improved Productivity 39 | // Reivew the Smart Autocomplete, Format Query, Shortcuts, and Query History 40 | 41 | // Page 17 - Click on the House icon to return to the main menu 42 | 43 | // Page 20 - Review the "Naming Standards" section 44 | 45 | // Page 21 - Code Cleanup 46 | // No code cleanup needed for this chapter 47 | -------------------------------------------------------------------------------- /Chapter Code/Chapter02.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 2: Creating and Managing the Snowflake Architecture 6 | 7 | 8 | // Page 23 - Prep Work 9 | // Create new worksheet: Chapter2 Creating and Managing Snowflake Architecture 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | // Page 32 - Optional 13 | // Navigate back to the worksheet, if needed 14 | // Create a new small virtual warehouse in UI: Original_WH 15 | // Increase the cluster size to medium 16 | // Scale back down but change to multi-cluster 17 | // Note if you create this optional virtual warehouse, be sure to drop it during code cleanup 18 | 19 | // Page 38 - Create a new virtual warehouse 20 | USE ROLE SYSADMIN; 21 | CREATE WAREHOUSE CH2_WH WITH WAREHOUSE_SIZE = MEDIUM 22 | AUTO_SUSPEND = 300 AUTO_RESUME = true INITIALLY_SUSPENDED = true; 23 | 24 | // Page 38 - Scaling up a virtual warehouse 25 | USE ROLE SYSADMIN; 26 | ALTER WAREHOUSE CH2_WH 27 | SET WAREHOUSE_SIZE = LARGE; 28 | 29 | // Page 39 - Set context for virtual warehouse to be used 30 | USE WAREHOUSE CH2_WH; 31 | 32 | // Page 39 - Set context for virtual warehouse to be used 33 | // Use the menu to set the context for the virtual warehouse 34 | 35 | // Page 39 - Editing a virtual warehouse from the Web UI 36 | // Navigate to Admin -> Warehouses 37 | // Refresh the page if needed 38 | // Select the Edit option from the ellipsis from the right, for the CH2_WH virtual warehouse 39 | 40 | // Page 43 - Create new virtual warehouse 41 | // Navigate back to the worksheet, if needed 42 | USE ROLE SYSADMIN; 43 | CREATE OR REPLACE WAREHOUSE ACCOUNTING_WH 44 | WITH Warehouse_Size = MEDIUM MIN_CLUSTER_COUNT = 1 45 | MAX_CLUSTER_COUNT = 6 SCALING_POLICY = 'STANDARD'; 46 | 47 | // Page 47 - Disable the Reseult Cache 48 | ALTER SESSION SET USE_CACHED_RESULT=FALSE; 49 | 50 | // Page 50 - Code Cleanup 51 | // Set the cached results back to true 52 | USE ROLE SYSADMIN; 53 | ALTER SESSION SET USE_CACHED_RESULT=TRUE; 54 | // Drop the virtual warehouses created in this chapter 55 | USE ROLE SYSADMIN; 56 | DROP WAREHOUSE CH2_WH; 57 | DROP WAREHOUSE ACCOUNTING_WH; 58 | -------------------------------------------------------------------------------- /Chapter Code/Chapter03.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 3: Creating and Managing Snowflake Secuirable Database Objects 6 | 7 | 8 | // Page 54 - Prep Work 9 | // Create new worksheet: Chapter3 Creating Database Objects 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | // Page 56 - Create a Permanent Database via the Web UI 13 | // Navigate to Data -> Databases 14 | // Confirm your role is set to SYSADMIN 15 | // Use the +Database button to create a new Snowflake database 16 | // Enter "DEMO3A_DB" ad the database name 17 | // Include a comment "Permanent Database for Chapter 3 Exercises" 18 | // Click the Create button 19 | 20 | // Page 58 - Create a Transient Database via the Worksheet 21 | // Navigate back to the worksheet 22 | // Confirm your role is set to SYSADMIN 23 | USE ROLE SYSADMIN; 24 | USE WAREHOUSE COMPUTE_WH; 25 | CREATE OR REPLACE TRANSIENT DATABASE DEMO3B_DB 26 | Comment = 'Transient Database for Chapter 3 Exercises'; 27 | 28 | // Page 59 - Via the Web UI, see the databases accessible to your role 29 | // Navigate to Databases UI and look to the right 30 | // Note that your role should be set to SYSADMIN 31 | 32 | // Page 59 - Via the worksheet, see the databases accessible to your role 33 | // Navigate back to the worksheet 34 | // Change role to ACCOUNTADMIN via the drop-down menu on the right 35 | // Be sure to notice the retention time for each database 36 | USE ROLE ACCOUNTADMIN; 37 | SHOW DATABASES; 38 | 39 | // Page 60 - Change the data retention time for a permanent database 40 | // Make sure your role is set to SYSADMIN 41 | USE ROLE SYSADMIN; 42 | ALTER DATABASE DEMO3A_DB 43 | SET DATA_RETENTION_TIME_IN_DAYS=10; 44 | 45 | //Page 61 - Attempt to change the retention time for a transiet database 46 | //will receive an error 47 | USE ROLE SYSADMIN; 48 | ALTER DATABASE DEMO3B_DB 49 | SET DATA_RETENTION_TIME_IN_DAYS=10; 50 | 51 | //Page 61 - Create a table in a transient database 52 | USE ROLE SYSADMIN; 53 | CREATE OR REPLACE TABLE DEMO3B_DB.PUBLIC.SUMMARY 54 | (CASH_AMT number, 55 | RECEIVABLES_AMT number, 56 | CUSTOMER_AMT number); 57 | 58 | // Page 62 - Using the SHOW TABLES command to see the details of tables 59 | SHOW TABLES; 60 | 61 | // Page 63 - Example 1 of how to create a new schema by setting context 62 | USE ROLE SYSADMIN; USE DATABASE DEMO3A_DB; 63 | CREATE OR REPLACE SCHEMA BANKING; 64 | 65 | // Page 64 - Example 2 of how to create a new schema using fully qualifed name 66 | USE ROLE SYSADMIN; 67 | CREATE OR REPLACE SCHEMA DEMO3A_DB.BANKING; 68 | 69 | // Page 65 - Using the SHOW SCHEMAS command to see the details of schemas 70 | SHOW SCHEMAS; 71 | 72 | // Page 66 - Change the retention time for a schema 73 | USE ROLE SYSADMIN; 74 | ALTER SCHEMA DEMO3A_DB.BANKING 75 | SET DATA_RETENTION_TIME_IN_DAYS=1; 76 | 77 | // Page 67 - Moving a table to a different (newly created) schema 78 | USE ROLE SYSADMIN; 79 | CREATE OR REPLACE SCHEMA DEMO3B_DB.BANKING; 80 | ALTER TABLE DEMO3B_DB.PUBLIC.SUMMARY 81 | RENAME TO DEMO3B_DB.BANKING.SUMMARY; 82 | 83 | // Page 64 - Create a schema with managed access 84 | USE ROLE SYSADMIN; USE DATABASE DEMO3A_DB; 85 | CREATE OR REPLACE SCHEMA MSCHEMA WITH MANAGED ACCESS; 86 | 87 | // Page 65 - Using the SHOW SCHEMAS command to see details of schemas 88 | SHOW SCHEMAS; 89 | 90 | // Page 67 - Information Schema for a database (Example #1) 91 | SELECT * FROM SNOWFLAKE_SAMPLE_DATA.INFORMATION_SCHEMA.DATABASES; 92 | 93 | // Page 67 - Information Schema for a database (Example #2) 94 | SELECT * FROM DEMO3A_DB.INFORMATION_SCHEMA.DATABASES; 95 | 96 | // Page 67 - Information schema for applicable roles (Example #1) 97 | SELECT * FROM SNOWFLAKE_SAMPLE_DATA.INFORMATION_SCHEMA.APPLICABLE_ROLES; 98 | 99 | // Page 67 - Information schema for applicable roles (Example #2) 100 | SELECT * FROM DEMO3A_DB.INFORMATION_SCHEMA.APPLICABLE_ROLES; 101 | 102 | // Page 69 - Information about schemas in the Snowflake sample database (Example #1) 103 | SELECT * FROM SNOWFLAKE_SAMPLE_DATA.INFORMATION_SCHEMA.SCHEMATA; 104 | 105 | // Page 69 - Information about schemas in the Snowflake sample database (Example #2) 106 | SHOW SCHEMAS IN DATABASE SNOWFLAKE_SAMPLE_DATA; 107 | 108 | // Page 69 - Information schema for table privileges (Example #1) 109 | SELECT * FROM DEMO3A_DB.INFORMATION_SCHEMA.TABLE_PRIVILEGES; 110 | 111 | // Page 69 - Information schema for table privileges (Example #2) 112 | SELECT * FROM DEMO3B_DB.INFORMATION_SCHEMA.TABLE_PRIVILEGES; 113 | 114 | // Page 70 - Show credits used over time by each virtual warehouse 115 | // Make sure your role is set to ACCOUNTADMIN 116 | USE ROLE ACCOUNTADMIN;USE DATABASE SNOWFLAKE;USE SCHEMA ACCOUNT_USAGE; 117 | USE WAREHOUSE COMPUTE_WH; 118 | SELECT start_time::date AS USAGE_DATE, WAREHOUSE_NAME, 119 | SUM(credits_used) AS TOTAL_CREDITS_CONSUMED 120 | FROM warehouse_metering_history 121 | WHERE start_time >= date_trunc(Month, current_date) 122 | GROUP BY 1,2 123 | ORDER BY 2,1; 124 | 125 | // Page 74 - Create some tables 126 | // Make sure you are using the SYSADMIN role 127 | USE ROLE SYSADMIN; USE DATABASE DEMO3A_DB; 128 | CREATE OR REPLACE SCHEMA BANKING; 129 | CREATE OR REPLACE TABLE CUSTOMER_ACCT 130 | (Customer_Account int, Amount int, transaction_ts timestamp); 131 | CREATE OR REPLACE TABLE CASH 132 | (Customer_Account int, Amount int, transaction_ts timestamp); 133 | CREATE OR REPLACE TABLE RECEIVABLES 134 | (Customer_Account int, Amount int, transaction_ts timestamp); 135 | 136 | 137 | // Page 74 - Creating a table without specifying the database or schema 138 | USE ROLE SYSADMIN; 139 | CREATE OR REPLACE TABLE NEWTABLE 140 | (Customer_Account int, 141 | Amount int, 142 | transaction_ts timestamp); 143 | 144 | // Page 75 - Drop the table, best practice is using fully qualified name 145 | // Make sure you are using the SYSADMIN role 146 | DROP TABLE DEMO3A_DB.BANKING.NEWTABLE; 147 | 148 | // Page 77 - Create a new view 149 | USE ROLE SYSADMIN; 150 | CREATE OR REPLACE VIEW DEMO3B_DB.PUBLIC.NEWVIEW AS 151 | SELECT CC_NAME 152 | FROM (SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCDS_SF100TCL.CALL_CENTER); 153 | 154 | // Page 77 - Create a new materializesd view 155 | USE ROLE SYSADMIN; 156 | CREATE OR REPLACE MATERIALIZED VIEW DEMO3B_DB.PUBLIC.NEWVIEW_MVW AS 157 | SELECT CC_NAME 158 | FROM (SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCDS_SF100TCL.CALL_CENTER); 159 | 160 | // Page 77 - Use the SHOW VIEWS command to see information on the views 161 | USE SCHEMA DEMO3B_DB.PUBLIC; 162 | SHOW VIEWS; 163 | 164 | // Page 78 - Create a materialized view 165 | CREATE OR REPLACE MATERIALIZED VIEW DEMO3B_DB.BANKING.SUMMARY_MVW AS 166 | SELECT * FROM (SELECT * FROM DEMO3B_DB.BANKING.SUMMARY); 167 | 168 | // Page 78 - Create a nonmaterialized view 169 | CREATE OR REPLACE VIEW DEMO3B_DB.BANKING.SUMMARY_VW AS 170 | SELECT * FROM (SELECT * FROM DEMO3B_DB.BANKING.SUMMARY); 171 | 172 | // Page 81 - Create a basic file format for loading JSON data into a stage 173 | USE ROLE SYSADMIN; USE DATABASE DEMO3B_DB; 174 | CREATE OR REPLACE FILE FORMAT FF_JSON TYPE = JSON; 175 | 176 | // Page 81 - Creating an internal stage using the recently created file format 177 | USE DATABASE DEMO3B_DB; USE SCHEMA BANKING; 178 | CREATE OR REPLACE TEMPORARY STAGE BANKING_STG FILE_FORMAT = FF_JSON; 179 | 180 | // Page 84 - Create a UDF to show the JavaScript properties available for UDFs and procedures 181 | USE ROLE SYSADMIN; 182 | CREATE OR REPLACE DATABASE DEMO3C_DB; 183 | CREATE OR REPLACE FUNCTION JS_PROPERTIES() 184 | RETURNS string LANGUAGE JAVASCRIPT AS 185 | $$ return Object.getOwnPropertyNames(this); $$; 186 | 187 | // Page 84 - Display the results of the recently created UDF 188 | SELECT JS_PROPERTIES(); 189 | 190 | // Page 84 - Creating a JavaScript UDF which returns a scalar result 191 | USE ROLE SYSADMIN; USE DATABASE DEMO3C_DB; 192 | CREATE OR REPLACE FUNCTION FACTORIAL(n variant) 193 | RETURNS variant LANGUAGE JAVASCRIPT AS 194 | 'var f=n; 195 | for (i=n-1; i>0; i--) { 196 | f=f*i} 197 | return f'; 198 | 199 | // Page 85 - Display the results of the recently created JavaScript UDF 200 | SELECT FACTORIAL(5); 201 | 202 | // Page 87 - Create a table with 100,000 rows from the demo database 203 | USE ROLE SYSADMIN; 204 | CREATE OR REPLACE DATABASE DEMO3D_DB; 205 | CREATE OR REPLACE TABLE DEMO3D_DB.PUBLIC.SALES AS 206 | (SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCDS_SF100TCL.WEB_SALES) 207 | LIMIT 100000; 208 | 209 | // Page 87 - Find products sold along with the product which has an SK of 1 210 | SELECT 1 AS INPUT_ITEM, WS_WEB_SITE_SK AS BASKET_ITEM, 211 | COUNT (DISTINCT WS_ORDER_NUMBER) BASKETS 212 | FROM DEMO3D_DB.PUBLIC.SALES 213 | WHERE WS_ORDER_NUMBER IN 214 | (SELECT WS_ORDER_NUMBER 215 | FROM DEMO3D_DB.PUBLIC.SALES 216 | WHERE WS_WEB_SITE_SK = 1) 217 | GROUP BY WS_WEB_SITE_SK 218 | ORDER BY 3 DESC, 2; 219 | 220 | // Page 88 - Create a Secure SQL UDF function 221 | USE ROLE SYSADMIN; 222 | CREATE OR REPLACE SECURE FUNCTION 223 | DEMO3D_DB.PUBLIC.GET_MKTBASKET(INPUT_WEB_SITE_SK number(38)) 224 | RETURNS TABLE (INPUT_ITEM NUMBER(38, 0), BASKET_ITEM NUMBER(38, 0), 225 | BASKETS NUMBER(38, 0)) AS 226 | 'SELECT input_web_site_sk, WS_WEB_SITE_SK as BASKET_ITEM, 227 | COUNT(DISTINCT WS_ORDER_NUMBER) BASKETS 228 | FROM DEMO3D_DB.PUBLIC.SALES 229 | WHERE WS_ORDER_NUMBER IN 230 | (SELECT WS_ORDER_NUMBER 231 | FROM DEMO3D_DB.PUBLIC.SALES 232 | WHERE WS_WEB_SITE_SK = input_web_site_sk) 233 | GROUP BY ws_web_site_sk 234 | ORDER BY 3 DESC, 2'; 235 | 236 | // Page 89 - Find products sold along with the product which has an SK of 1, without having access to underlying data 237 | SELECT * FROM TABLE(DEMO3D_DB.PUBLIC.GET_MKTBASKET(1)); 238 | 239 | // Page 89 - Create a stored procedure 240 | USE ROLE SYSADMIN; 241 | CREATE OR REPLACE DATABASE DEMO3E_DB; 242 | CREATE OR REPLACE PROCEDURE STOREDPROC1(ARGUMENT1 VARCHAR) 243 | RETURNS string not null 244 | language javascript AS 245 | $$ 246 | var INPUT_ARGUMENT1 = ARGUMENT1; 247 | var result = `${INPUT_ARGUMENT1}` 248 | return result; 249 | $$; 250 | 251 | // Page 89 - Call the stored procedure 252 | CALL STOREDPROC1('I really love Snowflake ❄'); 253 | 254 | // Page 90 - Look at information for Snowflake stored procedures 255 | SELECT * FROM DEMO3E_DB.INFORMATION_SCHEMA.PROCEDURES; 256 | 257 | // Page 90 - Create a stored procedure for deposits 258 | USE ROLE SYSADMIN; USE DATABASE DEMO3A_DB; USE SCHEMA BANKING; 259 | CREATE OR REPLACE PROCEDURE deposit(PARAM_ACCT FLOAT, PARAM_AMT FLOAT) 260 | returns STRING LANGUAGE javascript AS 261 | $$ 262 | var ret_val = ""; var cmd_debit = ""; var cmd_credit = ""; 263 | // INSERT data into tables 264 | cmd_debit = "INSERT INTO DEMO3A_DB.BANKING.CASH VALUES (" 265 | + PARAM_ACCT + "," + PARAM_AMT + ",current_timestamp());"; 266 | cmd_credit = "INSERT INTO DEMO3A_DB.BANKING.CUSTOMER_ACCT VALUES (" 267 | + PARAM_ACCT + "," + PARAM_AMT + ",current_timestamp());"; 268 | // BEGIN transaction 269 | snowflake.execute ({sqlText: cmd_debit}); 270 | snowflake.execute ({sqlText: cmd_credit}); 271 | ret_val = "Deposit Transaction Succeeded"; 272 | return ret_val; 273 | $$; 274 | 275 | // Page 91 - Create a stored procedure for withdrawal 276 | USE ROLE SYSADMIN;USE DATABASE DEMO3A_DB; USE SCHEMA BANKING; 277 | CREATE OR REPLACE PROCEDURE withdrawal(PARAM_ACCT FLOAT, PARAM_AMT FLOAT) 278 | returns STRING LANGUAGE javascript AS 279 | $$ 280 | var ret_val = ""; var cmd_debit = ""; var cmd_credit = ""; 281 | // INSERT data into tables 282 | cmd_debit = "INSERT INTO DEMO3A_DB.BANKING.CUSTOMER_ACCT VALUES (" 283 | + PARAM_ACCT + "," + (-PARAM_AMT) + ",current_timestamp());"; 284 | cmd_credit = "INSERT INTO DEMO3A_DB.BANKING.CASH VALUES (" 285 | + PARAM_ACCT + "," + (-PARAM_AMT) + ",current_timestamp());"; 286 | // BEGIN transaction 287 | snowflake.execute ({sqlText: cmd_debit}); 288 | snowflake.execute ({sqlText: cmd_credit}); 289 | ret_val = "Withdrawal Transaction Succeeded"; 290 | return ret_val; 291 | $$; 292 | 293 | // Page 91 - Create a stored procedure for loan_payment 294 | USE ROLE SYSADMIN;USE DATABASE DEMO3A_DB; USE SCHEMA BANKING; 295 | CREATE OR REPLACE PROCEDURE loan_payment(PARAM_ACCT FLOAT, PARAM_AMT FLOAT) 296 | returns STRING LANGUAGE javascript AS 297 | $$ 298 | var ret_val = ""; var cmd_debit = ""; var cmd_credit = ""; 299 | // INSERT data into the tables 300 | cmd_debit = "INSERT INTO DEMO3A_DB.BANKING.CASH VALUES (" 301 | + PARAM_ACCT + "," + PARAM_AMT + ",current_timestamp());"; 302 | cmd_credit = "INSERT INTO DEMO3A_DB.BANKING.RECEIVABLES VALUES (" 303 | + PARAM_ACCT + "," +(-PARAM_AMT) + ",current_timestamp());"; 304 | //BEGIN transaction 305 | snowflake.execute ({sqlText: cmd_debit}); 306 | snowflake.execute ({sqlText: cmd_credit}); 307 | ret_val = "Loan Payment Transaction Succeeded"; 308 | return ret_val; 309 | $$; 310 | 311 | // Page 91 - Run call statements for each of the stored procedures to test them 312 | CALL withdrawal(21, 100); 313 | CALL loan_payment(21, 100); 314 | CALL deposit(21, 100); 315 | 316 | // Page 91 - See what happened when we called the procedures 317 | SELECT CUSTOMER_ACCOUNT, AMOUNT FROM DEMO3A_DB.BANKING.CASH; 318 | 319 | // Page 92 - Truncate the tables 320 | USE ROLE SYSADMIN; USE DATABASE DEMO3A_DB; USE SCHEMA BANKING; 321 | TRUNCATE TABLE DEMO3A_DB.BANKING.CUSTOMER_ACCT; 322 | TRUNCATE TABLE DEMO3A_DB.BANKING.CASH; 323 | TRUNCATE TABLE DEMO3A_DB.BANKING.RECEIVABLES; 324 | 325 | // Page 92 - Confirm no data is in the tables, after being truncated 326 | SELECT CUSTOMER_ACCOUNT, AMOUNT FROM DEMO3A_DB.BANKING.CASH; 327 | 328 | // Page 92 - Call the stored procedures 329 | USE ROLE SYSADMIN; 330 | CALL deposit(21, 10000); 331 | CALL deposit(21, 400); 332 | CALL loan_payment(14, 1000); 333 | CALL withdrawal(21, 500); 334 | CALL deposit(72, 4000); 335 | CALL withdrawal(21, 250); 336 | 337 | // Page 92 - Create a stored procedure for Transactions Summary 338 | USE ROLE SYSADMIN; USE DATABASE DEMO3B_DB; USE SCHEMA BANKING; 339 | CREATE OR REPLACE PROCEDURE Transactions_Summary() 340 | returns STRING LANGUAGE javascript AS 341 | $$ 342 | var cmd_truncate = `TRUNCATE TABLE IF EXISTS DEMO3B_DB.BANKING.SUMMARY;` 343 | var sql = snowflake.createStatement({sqlText: cmd_truncate}); 344 | //Summarize Cash Amount 345 | var cmd_cash = `Insert into DEMO3B_DB.BANKING.SUMMARY (CASH_AMT) 346 | select sum(AMOUNT) from DEMO3A_DB.BANKING.CASH;` 347 | var sql = snowflake.createStatement({sqlText: cmd_cash}); 348 | //Summarize Receivables Amount 349 | var cmd_receivables = `Insert into DEMO3B_DB.BANKING.SUMMARY 350 | (RECEIVABLES_AMT) select sum(AMOUNT) from DEMO3A_DB.BANKING.RECEIVABLES;` 351 | var sql = snowflake.createStatement({sqlText: cmd_receivables}); 352 | //Summarize Customer Account Amount 353 | var cmd_customer = `Insert into DEMO3B_DB.BANKING.SUMMARY (CUSTOMER_AMT) 354 | select sum(AMOUNT) from DEMO3A_DB.BANKING.CUSTOMER_ACCT;` 355 | var sql = snowflake.createStatement({sqlText: cmd_customer}); 356 | //BEGIN transaction 357 | snowflake.execute ({sqlText: cmd_truncate}); 358 | snowflake.execute ({sqlText: cmd_cash}); 359 | snowflake.execute ({sqlText: cmd_receivables}); 360 | snowflake.execute ({sqlText: cmd_customer}); 361 | ret_val = "Transactions Successfully Summarized"; 362 | return ret_val; 363 | $$; 364 | 365 | // Page 93 - Call the Transactions Summary stored procedure 366 | CALL Transactions_Summary(); 367 | 368 | // Page 93 - Take a look at the contents of the table 369 | SELECT * FROM DEMO3B_DB.BANKING.SUMMARY; 370 | 371 | // Page 93 - Take a look at the contents of the materialized view 372 | USE ROLE SYSADMIN; USE DATABASE DEMO3B_DB;USE SCHEMA BANKING; 373 | SELECT * FROM DEMO3B_DB.BANKING.SUMMARY_MVW; 374 | 375 | // Page 93 - Take a look at the contents of the nonmaterialized view 376 | USE ROLE SYSADMIN; USE DATABASE DEMO3B_DB;USE SCHEMA BANKING; 377 | SELECT * FROM DEMO3B_DB.BANKING.SUMMARY_VW; 378 | 379 | // Page 93 - Create a stored procedure to drop a database 380 | USE ROLE SYSADMIN; USE DATABASE DEMO3E_DB; 381 | CREATE OR REPLACE PROCEDURE drop_db() 382 | RETURNS STRING NOT NULL LANGUAGE javascript AS 383 | $$ 384 | var cmd = `DROP DATABASE DEMO3A_DB;` 385 | var sql = snowflake.createStatement({sqlText: cmd}); 386 | var result = sql.execute(); 387 | return 'Database has been successfully dropped'; 388 | $$; 389 | 390 | // Page 94 - Call the procedure 391 | CALL drop_db(); 392 | 393 | // Page 94 - Replace the procedure to drop a different database 394 | USE ROLE SYSADMIN; 395 | CREATE OR REPLACE PROCEDURE drop_db() RETURNS STRING NOT NULL 396 | LANGUAGE javascript AS 397 | $$ 398 | var cmd = `DROP DATABASE "DEMO3B_DB";` 399 | var sql = snowflake.createStatement({sqlText: cmd}); 400 | var result = sql.execute(); 401 | return 'Database has been successfully dropped'; 402 | $$; 403 | 404 | // Page 94 - Create a task which will delay the stored procedure by 15 minutes 405 | USE ROLE SYSADMIN; USE DATABASE DEMO3E_DB; 406 | CREATE OR REPLACE TASK tsk_wait_15 407 | WAREHOUSE = COMPUTE_WH SCHEDULE = '15 MINUTE' 408 | AS CALL drop_db(); 409 | 410 | // Page 94 - ACCOUNTADMIN role is needed to grant the "Execute Task" ability to the SYSADMIN role 411 | USE ROLE ACCOUNTADMIN; 412 | GRANT EXECUTE TASK ON ACCOUNT TO ROLE SYSADMIN; 413 | 414 | // Page 94 - Resume the task because all taks are created in a suspended state 415 | USE ROLE SYSADMIN; 416 | ALTER TASK IF EXISTS tsk_wait_15 RESUME; 417 | 418 | // Page 94 - Check to see of the task is in a scheduled state 419 | SELECT * FROM table(information_schema.task_history 420 | (task_name => 'tsk_wait_15', 421 | scheduled_time_range_start => 422 | dateadd('hour', -1, current_timestamp()))); 423 | 424 | // Need to wait for 15 minutes to pass 425 | 426 | // Page 95 - Suspend the task 427 | USE ROLE SYSADMIN; 428 | ALTER TASK IF EXISTS tsk_15 SUSPEND; 429 | 430 | // Page 95 - Create a sequence 431 | USE ROLE SYSADMIN; USE DATABASE DEMO3E_DB; 432 | CREATE OR REPLACE SEQUENCE SEQ_01 START = 1 INCREMENT = 1; 433 | CREATE OR REPLACE TABLE SEQUENCE_TEST(i integer); 434 | 435 | // Page 95 - Execute the sequence three or four times; run each statement separately and view the results 436 | SELECT SEQ_01.NEXTVAL; 437 | 438 | SELECT SEQ_01.NEXTVAL; 439 | 440 | SELECT SEQ_01.NEXTVAL; 441 | 442 | SELECT SEQ_01.NEXTVAL; 443 | 444 | // Page 95 - Create a sequence 445 | USE ROLE SYSADMIN;USE DATABASE DEMO3E_DB; 446 | CREATE OR REPLACE SEQUENCE SEQ_02 START = 1 INCREMENT = 2; 447 | CREATE OR REPLACE TABLE SEQUENCE_TEST(i integer); 448 | 449 | // Page 95 - See the results of how the sequence is incremented 450 | SELECT SEQ_02.NEXTVAL a, SEQ_02.NEXTVAL b,SEQ_02.NEXTVAL c,SEQ_02.NEXTVAL d; 451 | 452 | // Page 97 - Statements to set things up for the stream example 453 | USE ROLE SYSADMIN; 454 | CREATE OR REPLACE DATABASE DEMO3F_DB; 455 | CREATE OR REPLACE SCHEMA BANKING; 456 | CREATE OR REPLACE TABLE BRANCH (ID varchar, City varchar, Amount number (20,2)); 457 | INSERT INTO BRANCH (ID, City, Amount) 458 | values 459 | (12001, 'Abilene', 5387.97), 460 | (12002, 'Barstow', 34478.10), 461 | (12003, 'Cadbury', 8994.63); 462 | 463 | // Page 97 - View the records in the table 464 | SELECT * FROM BRANCH; 465 | 466 | // Page 97 - Create two streams and use SHOW STREAMS to see details 467 | CREATE OR REPLACE STREAM STREAM_A ON TABLE BRANCH; 468 | CREATE OR REPLACE STREAM STREAM_B ON TABLE BRANCH; 469 | SHOW STREAMS; 470 | 471 | // Page 97 - Streams are empty; Result of statements will be "Query produced no results" 472 | SELECT * FROM STREAM_A; 473 | 474 | SELECT * FROM STREAM_B; 475 | 476 | // Page 97 - Insert some records into the table 477 | INSERT INTO BRANCH (ID, City, Amount) 478 | values 479 | (12004, 'Denton', 41242.93), 480 | (12005, 'Everett', 6175.22), 481 | (12006, 'Fargo', 443689.75); 482 | 483 | // Page 97 - See what is now in the table and each of the streams; run the statements one at a time 484 | SELECT * FROM BRANCH; 485 | 486 | SELECT * FROM STREAM_A; 487 | 488 | SELECT * FROM STREAM_B; 489 | 490 | // Page 97 - Create another stream 491 | CREATE OR REPLACE STREAM STREAM_C ON TABLE BRANCH; 492 | 493 | // Page 98 - Add more records to the table 494 | INSERT INTO BRANCH (ID, City, Amount) 495 | values 496 | (12007, 'Galveston', 351247.79), 497 | (12008, 'Houston', 917011.27); 498 | 499 | // Page 98 - Recreate Stream B 500 | CREATE OR REPLACE STREAM STREAM_B ON TABLE BRANCH; 501 | 502 | // Page 98 Delete the first record from each of the previous inserts 503 | DELETE FROM BRANCH WHERE ID = 12001; 504 | DELETE FROM BRANCH WHERE ID = 12004; 505 | DELETE FROM BRANCH WHERE ID = 12007; 506 | 507 | // Page 98 View the contents of the table and each stream; run one at a time 508 | SELECT * FROM BRANCH; 509 | 510 | SELECT * FROM STREAM_A; 511 | 512 | SELECT * FROM STREAM_B; 513 | 514 | SELECT * FROM STREAM_C; 515 | 516 | // Page 99 Update a record in the Branch table 517 | UPDATE BRANCH 518 | SET City = 'Fayetteville' WHERE ID = 12006; 519 | SELECT * FROM BRANCH; 520 | 521 | // Page 99 View the contents of the table and each stream; run one at a time 522 | SELECT * FROM BRANCH; 523 | 524 | SELECT * FROM STREAM_A; 525 | 526 | SELECT * FROM STREAM_B; 527 | 528 | SELECT * FROM STREAM_C; 529 | 530 | // Page 105 - Create a task admin role and grant necessary privileges 531 | USE ROLE SECURITYADMIN; 532 | CREATE ROLE TASKADMIN; 533 | 534 | USE ROLE ACCOUNTADMIN; 535 | GRANT EXECUTE TASK, EXECUTE MANAGED TASK ON ACCOUNT TO ROLE TASKADMIN; 536 | 537 | 538 | // Page 105 - Assign the role to a specific user role and back to the SYSADMIN 539 | USE ROLE SECURITYADMIN; 540 | // Replace with an actual role 541 | // GRANT ROLE TASKADMIN TO ROLE ; 542 | GRANT ROLE TASKADMIN TO ROLE SYSADMIN; 543 | 544 | // Page 105 - Create a new database and schema for use with demonstrating tasks 545 | USE ROLE ACCOUNTADMIN; 546 | USE WAREHOUSE COMPUTE_WH; 547 | USE DATABASE DEMO3F_DB; 548 | CREATE OR REPLACE SCHEMA TASKSDEMO; 549 | 550 | // Page 105 - Create a new table for use in demonstrating tasks 551 | CREATE OR REPLACE TABLE DEMO3F_DB.TASKSDEMO.PRODUCT 552 | (Prod_ID int, 553 | Prod_Desc varchar(), 554 | Category varchar(30), 555 | Segment varchar(20), 556 | Mfg_ID int, 557 | Mfg_Name varchar(50)); 558 | 559 | // Page 105 - Insert some values in the table 560 | INSERT INTO DEMO3F_DB.TASKSDEMO.PRODUCT values 561 | (1201, 'Product 1201', 'Category 1201', 'Segment 1201', '1201', 'Mfg 1201'); 562 | INSERT INTO DEMO3F_DB.TASKSDEMO.PRODUCT values 563 | (1202, 'Product 1202', 'Category 1202', 'Segment 1202', '1202', 'Mfg 1202'); 564 | INSERT INTO DEMO3F_DB.TASKSDEMO.PRODUCT values 565 | (1203, 'Product 1203', 'Category 1203', 'Segment 1203', '1203', 'Mfg 1203'); 566 | INSERT INTO DEMO3F_DB.TASKSDEMO.PRODUCT values 567 | (1204, 'Product 1204', 'Category 1204', 'Segment 1204', '1204', 'Mfg 1204'); 568 | INSERT INTO DEMO3F_DB.TASKSDEMO.PRODUCT values 569 | (1205, 'Product 1205', 'Category 1205', 'Segment 1205', '1205', 'Mfg 1205'); 570 | INSERT INTO DEMO3F_DB.TASKSDEMO.PRODUCT values 571 | (1206, 'Product 1206', 'Category 1206', 'Segment 1206', '1206', 'Mfg 1206'); 572 | 573 | // Page 105 - Create a new Sales table 574 | CREATE OR REPLACE TABLE DEMO3F_DB.TASKSDEMO.SALES 575 | (Prod_ID int, 576 | Customer varchar(), 577 | Zip varchar(), 578 | Qty int, 579 | Revenue decimal(10,2)); 580 | 581 | // Page 106 - Create a new stream 582 | CREATE OR REPLACE STREAM DEMO3F_DB.TASKSDEMO.SALES_STREAM 583 | ON TABLE DEMO3F_DB.TASKSDEMO.SALES 584 | APPEND_ONLY = TRUE; 585 | 586 | // Page 106 - Insert values into the table to test that the stream works as expected 587 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 588 | (1201, 'Amy Johnson', 45466, 45, 2345.67); 589 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 590 | (1201, 'Harold Robinson', 89701, 45, 2345.67); 591 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 592 | (1203, 'Chad Norton', 33236, 45, 2345.67); 593 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 594 | (1206, 'Horatio Simon', 75148, 45, 2345.67); 595 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 596 | (1205, 'Misty Crawford', 10001, 45, 2345.67); 597 | 598 | 599 | // Page 106 - Confirm that the values are included in the stream 600 | SELECT * FROM DEMO3F_DB.TASKSDEMO.SALES_STREAM; 601 | 602 | // Page 106 - Create a sales transaction table 603 | CREATE OR REPLACE TABLE DEMO3F_DB.TASKSDEMO.SALES_TRANSACT 604 | (Prod_ID int, 605 | Prod_Desc varchar(), 606 | Category varchar(30), 607 | Segment varchar(20), 608 | Mfg_ID int, 609 | Mfg_Name varchar(50), 610 | Customer varchar(), 611 | Zip varchar(), 612 | Qty int, 613 | Revenue decimal (10, 2), 614 | TS timestamp); 615 | 616 | // Page 106 - Manually enter some data 617 | INSERT INTO 618 | DEMO3F_DB.TASKSDEMO.SALES_TRANSACT 619 | (Prod_ID,Prod_Desc,Category,Segment,Mfg_Id, 620 | Mfg_Name,Customer,Zip,Qty,Revenue,TS) 621 | SELECT 622 | s.Prod_ID,p.Prod_Desc,p.Category,p.Segment,p.Mfg_ID, 623 | p.Mfg_Name,s.Customer,s.Zip,s.Qty,s.Revenue,current_timestamp 624 | FROM 625 | DEMO3F_DB.TASKSDEMO.SALES_STREAM s 626 | JOIN DEMO3F_DB.TASKSDEMO.PRODUCT p ON s.Prod_ID = p.Prod_ID; 627 | 628 | // Page 107 - Confirm that the records were inserted into the table 629 | SELECT * FROM DEMO3F_DB.TASKSDEMO.SALES_TRANSACT; 630 | 631 | // Page 107 - Automate the task 632 | CREATE OR REPLACE TASK DEMO3F_DB.TASKSDEMO.SALES_TASK 633 | WAREHOUSE = compute_wh 634 | SCHEDULE = '1 minute' 635 | WHEN system$stream_has_data('DEMO3F_DB.TASKSDEMO.SALES_STREAM') 636 | AS 637 | INSERT INTO 638 | DEMO3F_DB.TASKSDEMO.SALES_TRANSACT 639 | (Prod_ID,Prod_Desc,Category,Segment,Mfg_Id, 640 | Mfg_Name,Customer,Zip,Qty,Revenue,TS) 641 | SELECT 642 | s.Prod_ID,p.Prod_Desc,p.Category,p.Segment,p.Mfg_ID, 643 | p.Mfg_Name,s.Customer,s.Zip,s.Qty,s.Revenue,current_timestamp 644 | FROM 645 | DEMO3F_DB.TASKSDEMO.SALES_STREAM s 646 | JOIN DEMO3F_DB.TASKSDEMO.PRODUCT p ON s.Prod_ID = p.Prod_ID; 647 | ALTER TASK DEMO3F_DB.TASKSDEMO.SALES_TASK RESUME; 648 | 649 | // Page 107 - Insert values into the sales table 650 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 651 | (1201, 'Edward Jameson', 45466, 45, 2345.67); 652 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 653 | (1201, 'Margaret Volt', 89701, 45, 2345.67); 654 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 655 | (1203, 'Antoine Lancaster', 33236, 45, 2345.67); 656 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 657 | (1204, 'Esther Baker', 75148, 45, 2345.67); 658 | INSERT INTO DEMO3F_DB.TASKSDEMO.SALES VALUES 659 | (1206, 'Quintin Anderson', 10001, 45, 2345.67); 660 | 661 | // Page 108 - Confirm that the values were capted by the Sales stream 662 | SELECT * FROM DEMO3F_DB.TASKSDEMO.SALES_STREAM; 663 | 664 | // Wait for a minute 665 | 666 | // Page 108 - Confirm that the task worked 667 | SELECT * FROM DEMO3F_DB.TASKSDEMO.SALES_TRANSACT; 668 | 669 | // Page 108 - Suspend the task 670 | ALTER TASK DEMO3F_DB.TASKSDEMO.SALES_TASK SUSPEND; 671 | 672 | // Page 108 - Code Cleanup 673 | DROP DATABASE DEMO3C_DB; DROP DATABASE DEMO3D_DB; 674 | DROP DATABASE DEMO3E_DB; DROP DATABASE DEMO3F_DB; 675 | 676 | -------------------------------------------------------------------------------- /Chapter Code/Chapter04.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 4: Exploring Snowflake SQL Commands, Data Types, and Functions 6 | 7 | 8 | // Page 112 - Prep Work 9 | // Create new worksheet: Chapter4 Syntax Examples, Data Types, and Functions 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | // Page 115 - Navigate to Activity -> Query History and view the options 13 | 14 | // Page 118 - Createdatabase, schema, and tables to be used for chapter examples 15 | USE ROLE SYSADMIN; 16 | USE WAREHOUSE COMPUTE_WH; 17 | CREATE OR REPLACE DATABASE DEMO4_DB; 18 | CREATE OR REPLACE SCHEMA SUBQUERIES; 19 | CREATE OR REPLACE TABLE DEMO4_DB.SUBQUERIES.DERIVED 20 | (ID integer, AMT integer, Total integer); 21 | INSERT INTO DERIVED (ID, AMT, Total) 22 | VALUES (1,1000,4000),(2,2000,3500),(3,3000, 9900),(4,4000,3000), 23 | (5,5000,3700),(6,6000,2222); 24 | SELECT * FROM DEMO4_DB.SUBQUERIES.DERIVED; 25 | 26 | // Page 119 - Add a second table for use in a later example 27 | CREATE OR REPLACE TABLE DEMO4_DB.SUBQUERIES.TABLE2 28 | (ID integer, AMT integer, Total integer); 29 | INSERT INTO TABLE2 (ID, AMT, Total) 30 | VALUES (1,1000,8300),(2,1001,1900),(3,3000,4400),(4,1010,3535), 31 | (5,1200,3232),(6,1000,2222); 32 | SELECT * FROM DEMO4_DB.SUBQUERIES.TABLE2; 33 | 34 | // Page 120 - Execute an uncorrelated (i.e., independent) subquery 35 | SELECT ID, AMT 36 | FROM DEMO4_DB.SUBQUERIES.DERIVED 37 | WHERE AMT = (SELECT MAX(AMT) 38 | FROM DEMO4_DB.SUBQUERIES.TABLE2); 39 | 40 | // Page 120 - Execute a correlated query 41 | // Note that an error will be returned 42 | SELECT ID, AMT 43 | FROM DEMO4_DB.SUBQUERIES.DERIVED 44 | WHERE AMT = (SELECT AMT 45 | FROM DEMO4_DB.SUBQUERIES.TABLE2 46 | WHERE ID = ID); 47 | 48 | // Page 120 - Add MAX to the previous statement 49 | SELECT ID, AMT 50 | FROM DEMO4_DB.SUBQUERIES.DERIVED 51 | WHERE AMT = (SELECT MAX(AMT) 52 | FROM DEMO4_DB.SUBQUERIES.TABLE2 53 | WHERE ID = ID); 54 | 55 | // Page 120 - Change the equal sign to a greater than sign 56 | SELECT ID, AMT 57 | FROM DEMO4_DB.SUBQUERIES.DERIVED 58 | WHERE AMT > (SELECT MAX(AMT) 59 | FROM DEMO4_DB.SUBQUERIES.TABLE2 60 | WHERE ID = ID); 61 | 62 | // Page 121 - Change MAX to AVG 63 | SELECT ID, AMT 64 | FROM DEMO4_DB.SUBQUERIES.DERIVED 65 | WHERE AMT > (SELECT AVG(AMT) 66 | FROM DEMO4_DB.SUBQUERIES.TABLE2 67 | WHERE ID = ID); 68 | 69 | // Page 121 - Create a derived column from the AMT column and then create a second derived column 70 | SELECT ID, AMT, AMT * 10 as AMT1, AMT1 + 20 as AMT2 71 | FROM DEMO4_DB.SUBQUERIES.DERIVED; 72 | 73 | // Page 122 - Create a derived column to be consumed by an outer SELECT query 74 | SELECT sub.ID, sub.AMT, sub.AMT1 + 20 as AMT2 75 | FROM (SELECT ID, AMT, AMT * 10 as AMT1 76 | FROM DEMO4_DB.SUBQUERIES.DERIVED) AS sub; 77 | 78 | // Page 122 - Use a CTE subquery 79 | WITH CTE1 AS (SELECT ID, AMT, AMT * 10 as AMT2 80 | FROM DEMO4_DB.SUBQUERIES.DERIVED) 81 | SELECT a.ID, b.AMT, b.AMT2 + 20 as AMT2 82 | FROM DEMO4_DB.SUBQUERIES.DERIVED a 83 | JOIN CTE1 b ON(a.ID = b.ID); 84 | 85 | // Page 123 - Create a new schema and table for multirow insert testing 86 | USE ROLE SYSADMIN; 87 | CREATE OR REPLACE SCHEMA DEMO4_DB.TEST; 88 | CREATE OR REPLACE TABLE DEMO4_DB.TEST.TEST1 (ID integer, DEPT Varchar); 89 | INSERT INTO TEST1 (ID, DEPT) 90 | VALUES (1,'one'); 91 | SELECT * FROM DEMO4_DB.TEST.TEST1; 92 | 93 | // Page 123 - Insert a numerical value instead into the VARCHAR column 94 | USE ROLE SYSADMIN; 95 | CREATE OR REPLACE SCHEMA DEMO4_DB.TEST; 96 | CREATE OR REPLACE TABLE DEMO4_DB.TEST.TEST1 (ID integer, DEPT Varchar); 97 | INSERT INTO TEST1 (ID, DEPT) 98 | VALUES (1,1); 99 | SELECT * FROM DEMO4_DB.TEST.TEST1; 100 | 101 | // Page 123 - Inserting both types into the column 102 | //Error is expected 103 | USE ROLE SYSADMIN; 104 | CREATE OR REPLACE SCHEMA DEMO4_DB.TEST; 105 | CREATE OR REPLACE TABLE DEMO4_DB.TEST.TEST1 (ID integer, DEPT Varchar); 106 | INSERT INTO TEST1 (ID, DEPT) 107 | VALUES (1,'one'), (2,2); 108 | SELECT * FROM DEMO4_DB.TEST.TEST1; 109 | 110 | // Page 124 - Instead Insert to values with the same data type 111 | USE ROLE SYSADMIN; 112 | CREATE OR REPLACE SCHEMA DEMO4_DB.TEST; 113 | CREATE OR REPLACE TABLE DEMO4_DB.TEST.TEST1 (ID integer, DEPT Varchar); 114 | INSERT INTO TEST1 (ID, DEPT) 115 | VALUES (1,'one'), (2,'two'); 116 | SELECT * FROM DEMO4_DB.TEST.TEST1; 117 | 118 | // Page 124 - Now insert two numerical values 119 | USE ROLE SYSADMIN; 120 | CREATE OR REPLACE SCHEMA DEMO4_DB.TEST; 121 | CREATE OR REPLACE TABLE DEMO4_DB.TEST.TEST1 (ID integer, DEPT Varchar); 122 | INSERT INTO TEST1 (ID, DEPT) 123 | VALUES (1,1), (2,2); 124 | SELECT * FROM DEMO4_DB.TEST.TEST1; 125 | 126 | // Page 124 - Continue to add another value 127 | INSERT INTO TEST1 (ID, DEPT) 128 | VALUES (5, 'five'); 129 | SELECT * FROM DEMO4_DB.TEST.TEST1; 130 | 131 | // Page 128 - Fixed point numbers vary based on the data type 132 | USE ROLE SYSADMIN; 133 | CREATE OR REPLACE SCHEMA DEMO4_DB.DATATYPES; 134 | CREATE OR REPLACE TABLE NUMFIXED ( 135 | NUM NUMBER, 136 | NUM12 NUMBER(12, 0), 137 | DECIMAL DECIMAL (10, 2), 138 | INT INT, 139 | INTEGER INTEGER 140 | ); 141 | 142 | // Page 128 - See the results showing the fixed-point number data types 143 | DESC TABLE NUMFIXED; 144 | 145 | // Page 128 - Compare fixed-point numbers to floating-point numbers 146 | USE ROLE SYSADMIN; USE SCHEMA DEMO4_DB.DATATYPES; 147 | CREATE OR REPLACE TABLE NUMFLOAT ( 148 | FLOAT FLOAT, 149 | DOUBLE DOUBLE, 150 | DP DOUBLE PRECISION, 151 | REAL REAL 152 | ); 153 | 154 | // Page 128 - See the results showing the data types 155 | DESC TABLE NUMFLOAT; 156 | 157 | // Page 129 - Create text strings 158 | USE ROLE SYSADMIN; USE SCHEMA DEMO4_DB.DATATYPES; 159 | CREATE OR REPLACE TABLE TEXTSTRING( 160 | VARCHAR VARCHAR, 161 | V100 VARCHAR(100), 162 | CHAR CHAR, 163 | C100 CHAR(100), 164 | STRING STRING, 165 | S100 STRING(100), 166 | TEXT TEXT, 167 | T100 TEXT(100) 168 | ); 169 | 170 | // Page 130 - See the results showing the data types 171 | DESC TABLE TEXTSTRING; 172 | 173 | // Page 132 - Look at a few rows in the sample weather table 174 | USE ROLE SYSADMIN; 175 | USE SCHEMA SNOWFLAKE_SAMPLE_DATA.WEATHER; 176 | SELECT * FROM DAILY_16_TOTAL 177 | LIMIT 5; 178 | 179 | // Page 132 - Look at the city data in the VARIANT column 180 | SELECT v:city 181 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 182 | LIMIT 10; 183 | 184 | // Page 133 - Break out the CITY data and list in a logical order 185 | SELECT v:city:id, v:city:name, v:city:country, v:city:coord 186 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 187 | LIMIT 10; 188 | 189 | // Page 134 - Cast VARIANT data type to a VARCHAR data type and assign meaningful labels 190 | SELECT v:city:id AS ID, v:city:name AS CITY, 191 | v:city:country AS COUNTRY, v:city:coord:lat AS LATITUDE, 192 | v:city:coord:lon AS LONGITUDE 193 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 194 | LIMIT 10; 195 | 196 | // Page 134 - Break out the DATA column, which is stored as an array 197 | SELECT v:city:id AS ID, v:city:name::varchar AS city, 198 | v:city.country::varchar AS country, v:city:coord:lon 199 | AS longitude, v:city:coord:lat AS latitude 200 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 201 | LIMIT 10; 202 | 203 | // Page 134 - Describe the results of the last query 204 | DESC RESULT LAST_QUERY_ID(); 205 | 206 | // Page 134 - Look at more DATA in the VARIANT column 207 | SELECT v:data 208 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 209 | LIMIT 10; 210 | 211 | // Page 135 - Look at an array element 212 | SELECT v:data[5] 213 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 214 | LIMIT 10; 215 | 216 | // Page 135 - Look at humidity value for a particiular day for a specific city and country 217 | SELECT v:city:name AS city, v:city:country AS country, 218 | v:data[0]:humidity AS HUMIDITY 219 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 220 | LIMIT 10; 221 | 222 | // Page 135 - Include the first two data elements for humidity and the day temperature 223 | SELECT v:data[0]:dt::timestamp AS TIME, 224 | v:data[0]:humidity AS HUMIDITY0, v:data[0]:temp:day AS DAY_TEMP0, 225 | v:data[1]:humidity AS HUMIDITY1, v:data[1]:temp:day AS DAY_TEMP1, 226 | v:data AS DATA 227 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL 228 | LIMIT 100; 229 | 230 | // Page 136 - Use the LATERNAL FLATTEN 231 | SELECT d.value:dt::timestamp AS TIME, 232 | v:city:name AS CITY, v:city:country AS COUNTRY, 233 | d.path AS PATH, d.value:humidity AS HUMIDITY, 234 | d.value:temp:day AS DAY_TEMP,v:data AS DATA 235 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL, 236 | LATERAL FLATTEN(input => daily_16_total.v:data) d 237 | LIMIT 100; 238 | 239 | // Page 137 - Use a nested FLATTEN 240 | SELECT d.value:dt::timestamp AS TIME, 241 | t.key, 242 | v:city:name AS CITY, v:city:country AS COUNTRY, 243 | d.path AS PATH, 244 | d.value:humidity AS HUMIDITY, 245 | d.value:temp:day AS DAY_TEMP, 246 | d.value:temp:night AS NIGHT_TEMP, 247 | v:data AS data 248 | FROM SNOWFLAKE_SAMPLE_DATA.WEATHER.DAILY_16_TOTAL, 249 | LATERAL FLATTEN(input => daily_16_total.v:data) d, 250 | LATERAL FLATTEN(input => d.value:temp) t 251 | WHERE v:city:id = 1274693 252 | LIMIT 100; 253 | 254 | // Page 142 - Example of an Aggregate Function 255 | SELECT LETTER, SUM(LOCATION) as AGGREGATE 256 | FROM (SELECT 'A' as LETTER, 1 as LOCATION 257 | UNION ALL (SELECT 'A' as LETTER,1 as LOCATION) 258 | UNION ALL (SELECT 'E' as LETTER,5 as LOCATION) 259 | ) as AGG_TABLE 260 | GROUP BY LETTER; 261 | 262 | // Page 142 - Example of a Window Function 263 | SELECT LETTER, SUM(LOCATION) OVER (PARTITION BY LETTER) as WINDOW_FUNCTION 264 | FROM (SELECT 'A' as LETTER, 1 as LOCATION 265 | UNION ALL (SELECT 'A' as LETTER, 1 as LOCATION) 266 | UNION ALL (SELECT 'E' as LETTER, 5 as LOCATION) 267 | ) as WINDOW_TABLE; 268 | 269 | // Page 145 - Code Cleanup 270 | DROP DATABASE DEMO4_DB; -------------------------------------------------------------------------------- /Chapter Code/Chapter05.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 5: Leveraging Snowflake Access Controls 6 | 7 | 8 | // Page 148 - Prep Work 9 | // Create new worksheet: Chapter5 Snowflake Access Controls 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | // Page 150 - Create Virtual Warehouses 13 | USE ROLE SYSADMIN; 14 | USE WAREHOUSE COMPUTE_WH; 15 | CREATE OR REPLACE WAREHOUSE VW1_WH WITH WAREHOUSE_SIZE='X-SMALL' 16 | INITIALLY_SUSPENDED=true; 17 | CREATE OR REPLACE WAREHOUSE VW2_WH WITH WAREHOUSE_SIZE='X-SMALL' 18 | INITIALLY_SUSPENDED=true; 19 | CREATE OR REPLACE WAREHOUSE VW3_WH WITH WAREHOUSE_SIZE='X-SMALL' 20 | INITIALLY_SUSPENDED=true; 21 | 22 | // Page 151 - SHOW command will confirm the virtual warehouses were created 23 | SHOW WAREHOUSES; 24 | 25 | // Page 151 - SHOW command will confirm the virtual warehouses available to the SYSADMIN role 26 | USE ROLE SYSADMIN; 27 | SHOW DATABASES; 28 | 29 | // Page 151 - SHOW command will confirm the virtual warehouses available to the PUBLIC role 30 | USE ROLE PUBLIC; 31 | SHOW DATABASES; 32 | 33 | // Page 151 - SHOW command will confirm the virtual warehouses available to the ACCOUNTADMIN role 34 | USE ROLE ACCOUNTADMIN; 35 | SHOW DATABASES; 36 | 37 | // Page 152 - Create schemas right after createing database and then create schema with fully qualified name 38 | USE ROLE SYSADMIN; 39 | CREATE OR REPLACE DATABASE DB1; 40 | CREATE OR REPLACE DATABASE DB2; 41 | CREATE OR REPLACE SCHEMA DB2_SCHEMA1; 42 | CREATE OR REPLACE SCHEMA DB2_SCHEMA2; 43 | CREATE OR REPLACE SCHEMA DB1.DB1_SCHEMA1; 44 | 45 | // Page 152 - Use the SHOW command to confirm the details of the databases 46 | SHOW DATABASES; 47 | 48 | // Page 152 - Use the ACCOUNTADMIN role to create a new Resource Monitor 49 | USE ROLE ACCOUNTADMIN; 50 | CREATE OR REPLACE RESOURCE MONITOR MONITOR1_RM WITH CREDIT_QUOTA=10000 51 | TRIGGERS ON 75 PERCENT DO NOTIFY 52 | ON 98 PERCENT DO SUSPEND 53 | ON 105 PERCENT DO SUSPEND_IMMEDIATE; 54 | 55 | // Page 152 - Use the SHOW command to confirm the Resource Monitors that were created 56 | SHOW RESOURCE MONITORS; 57 | 58 | // Page 153 - Create some new users 59 | USE ROLE USERADMIN; 60 | CREATE OR REPLACE USER USER1 LOGIN_NAME=ARNOLD; 61 | CREATE OR REPLACE USER USER2 LOGIN_NAME=BEATRICE; 62 | CREATE OR REPLACE USER USER3 LOGIN_NAME=COLLIN; 63 | CREATE OR REPLACE USER USER4 LOGIN_NAME=DIEDRE; 64 | 65 | // Page 153 - Use the SHOW command for the USERADMIN role 66 | // Error is expected 67 | USE ROLE USERADMIN; 68 | SHOW USERS; 69 | 70 | // Page 153 - Use the SHOW command for the SECURITYADMIN role 71 | USE ROLE SECURITYADMIN; 72 | SHOW USERS; 73 | 74 | // Page 156 - Use the SHOW command for the USERADMIN role to display roles 75 | USE ROLE USERADMIN; 76 | SHOW ROLES; 77 | 78 | // Page 156 - Use the SHOW command for the SECURITYADMIN role to display roles 79 | USE ROLE SECURITYADMIN; 80 | SHOW ROLES; 81 | 82 | // Page 157 - Create 10 custom roles 83 | USE ROLE USERADMIN; 84 | CREATE OR REPLACE ROLE DATA_SCIENTIST; 85 | CREATE OR REPLACE ROLE ANALYST_SR; 86 | CREATE OR REPLACE ROLE ANALYST_JR; 87 | CREATE OR REPLACE ROLE DATA_EXCHANGE_ASST; 88 | CREATE OR REPLACE ROLE ACCOUNTANT_SR; 89 | CREATE OR REPLACE ROLE ACCOUNTANT_JR; 90 | CREATE OR REPLACE ROLE PRD_DBA; 91 | CREATE OR REPLACE ROLE DATA_ENGINEER; 92 | CREATE OR REPLACE ROLE DEVELOPER_SR; 93 | CREATE OR REPLACE ROLE DEVELOPER_JR; 94 | SHOW ROLES; 95 | 96 | // Page 158 - Create system service account roles 97 | USE ROLE USERADMIN; 98 | CREATE OR REPLACE ROLE LOADER; 99 | CREATE OR REPLACE ROLE VISUALIZER; 100 | CREATE OR REPLACE ROLE REPORTING; 101 | CREATE OR REPLACE ROLE MONITORING; 102 | 103 | // Page 158 - Create system object access roles 104 | USE ROLE USERADMIN; 105 | CREATE OR REPLACE ROLE DB1_SCHEMA1_READONLY; 106 | CREATE OR REPLACE ROLE DB1_SCHEMA1_ALL; 107 | CREATE OR REPLACE ROLE DB2_SCHEMA1_READONLY; 108 | CREATE OR REPLACE ROLE DB2_SCHEMA1_ALL; 109 | CREATE OR REPLACE ROLE DB2_SCHEMA2_READONLY; 110 | CREATE OR REPLACE ROLE DB2_SCHEMA2_ALL; 111 | CREATE OR REPLACE ROLE RM1_MODIFY; 112 | CREATE OR REPLACE ROLE WH1_USAGE; 113 | CREATE OR REPLACE ROLE WH2_USAGE; 114 | CREATE OR REPLACE ROLE WH3_USAGE; 115 | CREATE OR REPLACE ROLE DB1_MONITOR; 116 | CREATE OR REPLACE ROLE DB2_MONITOR; 117 | CREATE OR REPLACE ROLE WH1_MONITOR; 118 | CREATE OR REPLACE ROLE WH2_MONITOR; 119 | CREATE OR REPLACE ROLE WH3_MONITOR; 120 | CREATE OR REPLACE ROLE RM1_MONITOR; 121 | 122 | // Page 160 - Complete the system-level role hierarchy assignments 123 | USE ROLE USERADMIN; 124 | GRANT ROLE RM1_MONITOR TO ROLE MONITORING; 125 | GRANT ROLE WH1_MONITOR TO ROLE MONITORING; 126 | GRANT ROLE WH2_MONITOR TO ROLE MONITORING; 127 | GRANT ROLE WH3_MONITOR TO ROLE MONITORING; 128 | GRANT ROLE DB1_MONITOR TO ROLE MONITORING; 129 | GRANT ROLE DB2_MONITOR TO ROLE MONITORING; 130 | GRANT ROLE WH3_USAGE TO ROLE MONITORING; 131 | 132 | GRANT ROLE DB1_SCHEMA1_ALL TO ROLE LOADER; 133 | GRANT ROLE DB2_SCHEMA1_ALL TO ROLE LOADER; 134 | GRANT ROLE DB2_SCHEMA2_ALL TO ROLE LOADER; 135 | GRANT ROLE WH3_USAGE TO ROLE LOADER; 136 | 137 | GRANT ROLE DB2_SCHEMA1_READONLY TO ROLE VISUALIZER; 138 | GRANT ROLE DB2_SCHEMA2_READONLY TO ROLE VISUALIZER; 139 | GRANT ROLE WH3_USAGE TO ROLE VISUALIZER; 140 | 141 | GRANT ROLE DB1_SCHEMA1_READONLY TO ROLE REPORTING; 142 | GRANT ROLE DB2_SCHEMA1_READONLY TO ROLE REPORTING; 143 | GRANT ROLE DB2_SCHEMA2_READONLY TO ROLE REPORTING; 144 | 145 | GRANT ROLE WH3_USAGE TO ROLE REPORTING; 146 | GRANT ROLE MONITORING TO ROLE ACCOUNTANT_SR; 147 | GRANT ROLE LOADER TO ROLE DEVELOPER_SR; 148 | GRANT ROLE VISUALIZER TO ROLE ANALYST_JR; 149 | 150 | GRANT ROLE REPORTING TO ROLE ACCOUNTANT_JR; 151 | GRANT ROLE RM1_MODIFY TO ROLE ACCOUNTANT_SR; 152 | 153 | // Page 161 - Complete the functional role hierarchy assignment 154 | USE ROLE USERADMIN; 155 | GRANT ROLE ACCOUNTANT_JR TO ROLE ACCOUNTANT_SR; 156 | GRANT ROLE ANALYST_JR TO ROLE ANALYST_SR; 157 | GRANT ROLE ANALYST_SR TO ROLE DATA_SCIENTIST; 158 | GRANT ROLE DEVELOPER_JR TO ROLE DEVELOPER_SR; 159 | GRANT ROLE DEVELOPER_SR TO ROLE DATA_ENGINEER; 160 | GRANT ROLE DATA_ENGINEER TO ROLE PRD_DBA; 161 | GRANT ROLE ACCOUNTANT_SR TO ROLE ACCOUNTADMIN; 162 | GRANT ROLE DATA_EXCHANGE_ASST TO ROLE ACCOUNTADMIN; 163 | GRANT ROLE DATA_SCIENTIST TO ROLE SYSADMIN; 164 | GRANT ROLE PRD_DBA TO ROLE SYSADMIN; 165 | 166 | // Page 161 - Grant usage of virtual warehouse to IT and business roles 167 | GRANT ROLE WH1_USAGE TO ROLE DEVELOPER_JR; 168 | GRANT ROLE WH1_USAGE TO ROLE DEVELOPER_SR; 169 | GRANT ROLE WH1_USAGE TO ROLE DATA_ENGINEER; 170 | GRANT ROLE WH1_USAGE TO ROLE PRD_DBA; 171 | 172 | GRANT ROLE WH2_USAGE TO ROLE ACCOUNTANT_JR; 173 | GRANT ROLE WH2_USAGE TO ROLE ACCOUNTANT_SR; 174 | GRANT ROLE WH2_USAGE TO ROLE DATA_EXCHANGE_ASST; 175 | GRANT ROLE WH2_USAGE TO ROLE ANALYST_JR; 176 | GRANT ROLE WH2_USAGE TO ROLE ANALYST_SR; 177 | GRANT ROLE WH2_USAGE TO ROLE DATA_SCIENTIST; 178 | 179 | // Page 162 - Grant privileges to the functional roles and to grant privileges to custom roles only ACCOUNTADMIN can grant 180 | USE ROLE ACCOUNTADMIN; 181 | GRANT CREATE DATA EXCHANGE LISTING ON ACCOUNT TO ROLE DATA_EXCHANGE_ASST; 182 | GRANT IMPORT SHARE ON ACCOUNT TO ROLE DATA_EXCHANGE_ASST; 183 | GRANT CREATE SHARE ON ACCOUNT TO ROLE DATA_EXCHANGE_ASST; 184 | GRANT IMPORTED PRIVILEGES ON DATABASE SNOWFLAKE TO ROLE MONITORING; 185 | GRANT MONITOR ON RESOURCE MONITOR MONITOR1_RM TO ROLE MONITORING; 186 | GRANT MONITOR USAGE ON ACCOUNT TO ROLE ACCOUNTANT_JR; 187 | GRANT APPLY MASKING POLICY ON ACCOUNT TO ROLE ACCOUNTANT_SR; 188 | GRANT MONITOR EXECUTION ON ACCOUNT TO ROLE ACCOUNTANT_SR; 189 | GRANT MODIFY ON RESOURCE MONITOR MONITOR1_RM TO ROLE ACCOUNTANT_SR; 190 | 191 | // Page 164 - Grant privileges 192 | USE ROLE SYSADMIN; 193 | GRANT USAGE ON DATABASE DB1 TO ROLE DB1_SCHEMA1_READONLY; 194 | GRANT USAGE ON DATABASE DB2 TO ROLE DB2_SCHEMA1_READONLY; 195 | GRANT USAGE ON DATABASE DB2 TO ROLE DB2_SCHEMA2_READONLY; 196 | GRANT USAGE ON SCHEMA DB1.DB1_SCHEMA1 TO ROLE DB1_SCHEMA1_READONLY; 197 | GRANT USAGE ON SCHEMA DB2.DB2_SCHEMA1 TO ROLE DB2_SCHEMA1_READONLY; 198 | GRANT USAGE ON SCHEMA DB2.DB2_SCHEMA2 TO ROLE DB2_SCHEMA2_READONLY; 199 | 200 | 201 | GRANT SELECT ON ALL TABLES IN SCHEMA DB1.DB1_SCHEMA1 202 | TO ROLE DB1_SCHEMA1_READONLY; 203 | GRANT SELECT ON ALL TABLES IN SCHEMA DB2.DB2_SCHEMA1 204 | TO ROLE DB2_SCHEMA1_READONLY; 205 | GRANT SELECT ON ALL TABLES IN SCHEMA DB2.DB2_SCHEMA2 206 | TO ROLE DB1_SCHEMA1_READONLY; 207 | GRANT ALL ON SCHEMA DB1.DB1_SCHEMA1 TO ROLE DB1_SCHEMA1_ALL; 208 | GRANT ALL ON SCHEMA DB2.DB2_SCHEMA1 TO ROLE DB2_SCHEMA1_ALL; 209 | GRANT ALL ON SCHEMA DB2.DB2_SCHEMA2 TO ROLE DB2_SCHEMA2_ALL; 210 | GRANT MONITOR ON DATABASE DB1 TO ROLE DB1_MONITOR; 211 | GRANT MONITOR ON DATABASE DB2 TO ROLE DB2_MONITOR; 212 | GRANT MONITOR ON WAREHOUSE VW1_WH TO ROLE WH1_MONITOR; 213 | GRANT MONITOR ON WAREHOUSE VW2_WH TO ROLE WH2_MONITOR; 214 | GRANT MONITOR ON WAREHOUSE VW3_WH TO ROLE WH3_MONITOR; 215 | GRANT USAGE ON WAREHOUSE VW1_WH TO WH1_USAGE; 216 | GRANT USAGE ON WAREHOUSE VW2_WH TO WH2_USAGE; 217 | GRANT USAGE ON WAREHOUSE VW3_WH TO WH3_USAGE; 218 | 219 | // Page 165 - Grant FUTURE direct assigned privileges 220 | USE ROLE ACCOUNTADMIN; 221 | GRANT SELECT ON FUTURE TABLES IN SCHEMA DB1.DB1_SCHEMA1 222 | TO ROLE DB1_SCHEMA1_READONLY; 223 | GRANT SELECT ON FUTURE TABLES IN SCHEMA DB2.DB2_SCHEMA1 224 | TO ROLE DB2_SCHEMA1_READONLY; 225 | GRANT SELECT ON FUTURE TABLES IN SCHEMA DB2.DB2_SCHEMA2 226 | TO ROLE DB2_SCHEMA2_READONLY; 227 | GRANT SELECT ON FUTURE TABLES IN SCHEMA DB1.DB1_SCHEMA1 TO ROLE DB1_SCHEMA1_ALL; 228 | GRANT SELECT ON FUTURE TABLES IN SCHEMA DB2.DB2_SCHEMA1 TO ROLE DB2_SCHEMA1_ALL; 229 | GRANT SELECT ON FUTURE TABLES IN SCHEMA DB2.DB2_SCHEMA2 TO ROLE DB2_SCHEMA2_ALL; 230 | 231 | // Page 165 - Assign roles to the users 232 | USE ROLE USERADMIN; 233 | GRANT ROLE DATA_EXCHANGE_ASST TO USER USER1; 234 | GRANT ROLE DATA_SCIENTIST TO USER USER2; 235 | GRANT ROLE ACCOUNTANT_SR TO USER USER3; 236 | GRANT ROLE PRD_DBA TO USER USER4; 237 | 238 | // Page 166 - Validating our work 239 | // Error is expected 240 | USE ROLE ACCOUNTANT_JR; 241 | SELECT * FROM SNOWFLAKE.ACCOUNT_USAGE.QUERY_HISTORY WHERE QUERY_TYPE = 'GRANT'; 242 | 243 | // Page 167 - Validating our work 244 | USE ROLE ACCOUNTANT_SR; 245 | USE WAREHOUSE VW2_WH; 246 | SELECT * FROM SNOWFLAKE.ACCOUNT_USAGE.QUERY_HISTORY WHERE QUERY_TYPE ='GRANT'; 247 | 248 | // Page 167 - Use the SHOW command to see the databases avaialable to the SYSADMIN role 249 | USE ROLE SYSADMIN; 250 | SHOW DATABASES; 251 | 252 | // Page 167 - Take a look at the tables in the DB1_SCHEMA1 schema 253 | USE SCHEMA DB1_SCHEMA1; 254 | SHOW TABLES; 255 | 256 | // Page 167 - Create a table 257 | CREATE OR REPLACE TABLE DB1.DB1_SCHEMA1.TABLE1 (a varchar); 258 | INSERT INTO TABLE1 VALUES ('A'); 259 | 260 | // Page 167 - Confirm the table was created 261 | SHOW TABLES; 262 | 263 | // Page 168 - Test if the REPORTING role can access the table 264 | USE ROLE REPORTING; 265 | USE WAREHOUSE VW3_WH; 266 | SELECT * FROM DB1.DB1_SCHEMA1.TABLE1; 267 | 268 | // Page 168 - Test if the VISUALIZER role can access the table 269 | // Error is expected 270 | USE ROLE VISUALIZER; 271 | SELECT * FROM DB1.DB1_SCHEMA1.TABLE1; 272 | 273 | // Page 168 - Additional queries to try 274 | USE ROLE ACCOUNTANT_SR; 275 | USE WAREHOUSE VW3_WH; 276 | SELECT * FROM SNOWFLAKE.ACCOUNT_USAGE.GRANTS_TO_USERS; 277 | SHOW GRANTS ON ACCOUNT; 278 | SHOW GRANTS ON DATABASE DB1; 279 | SHOW GRANTS OF ROLE ANALYST_SR; 280 | SHOW FUTURE GRANTS IN DATABASE DB1; 281 | SHOW FUTURE GRANTS IN SCHEMA DB1.DB1_SCHEMA1; 282 | 283 | // Page 169 Grant then Revoke a privilege 284 | USE ROLE ACCOUNTADMIN; 285 | GRANT MONITOR USAGE ON ACCOUNT TO ROLE ANALYST_JR; 286 | USE ROLE USERADMIN; 287 | REVOKE MONITOR USAGE ON ACCOUNT FROM ROLE ANALYST_JR; 288 | 289 | // Page 169 - Create a new user 290 | USE ROLE USERADMIN; 291 | CREATE OR REPLACE USER USER10 292 | PASSWORD='123' 293 | LOGIN_NAME = ABARNETT 294 | DISPLAY_NAME = AMY 295 | FIRST_NAME = AMY 296 | LAST_NAME = BARNETT 297 | EMAIL = 'ABARNETT@COMPANY.COM' 298 | MUST_CHANGE_PASSWORD=TRUE; 299 | 300 | // Page 169 - Set up an expiration time for a user 301 | USE ROLE USERADMIN; 302 | ALTER USER USER10 SET DAYS_TO_EXPIRY = 30; 303 | 304 | // Page 170 - assign default virtual warehouse and role that does not exist 305 | 306 | USE ROLE USERADMIN; 307 | ALTER USER USER10 SET DEFAULT_WAREHOUSE=WAREHOUSE52_WH; 308 | 309 | USE ROLE USERADMIN; 310 | ALTER USER USER10 SET DEFAULT_ROLE=IMAGINARY_ROLE; 311 | 312 | // Sign out of your account and sign in as USER10 to test what happened as a result of the previous statements 313 | // Sign back in to your main account 314 | 315 | // Page 171 - Set some correct defaults now for USER10 316 | USE ROLE USERADMIN; 317 | GRANT ROLE ACCOUNTANT_SR TO USER USER10; 318 | ALTER USER USER10 SET DEFAULT_NAMESPACE=SNOWFLAKE.ACCOUNT_USAGE; 319 | ALTER USER USER10 SET DEFAULT_WAREHOUSE=VW2_WH; 320 | ALTER USER USER10 SET DEFAULT_ROLE = ACCOUNTANT_SR; 321 | ALTER USER USER10 UNSET DEFAULT_WAREHOUSE; 322 | 323 | // Sign out of your account again and sign in as USER10 324 | // Sign back in to your main account 325 | 326 | // Page 171 - Immediately clear a lock for a user 327 | USE ROLE USERADMIN; 328 | ALTER USER USER10 SET MINS_TO_UNLOCK=0; 329 | 330 | // Page 171 - Attempt to reset a user's password with an unacceptable password 331 | // Error is expected 332 | USE ROLE USERADMIN; 333 | ALTER USER USER10 SET PASSWORD = '123' 334 | MUST_CHANGE_PASSWORD = TRUE; 335 | 336 | // Page 172 - Reset a user's password correctly 337 | USE ROLE USERADMIN; 338 | ALTER USER USER10 SET PASSWORD = '123456Aa' 339 | MUST_CHANGE_PASSWORD = TRUE; 340 | 341 | // Page 172 - Demonstrate how the SECURITY admin can run the same statements 342 | USE ROLE SECURITYADMIN; 343 | ALTER USER USER10 SET PASSWORD = '123456Bb' 344 | MUST_CHANGE_PASSWORD = TRUE; 345 | 346 | // Page 172 - Abort a user's queries and prevent any new queries 347 | USE ROLE USERADMIN; 348 | ALTER USER USER10 SET DISABLED = TRUE; 349 | 350 | // Page 172 - Use the DESC command to get a listing of user's values 351 | USE ROLE USERADMIN; 352 | DESC USER USER10; 353 | 354 | // Page 173 - Reset value back to default value and check the results 355 | USE ROLE USERADMIN; 356 | ALTER USER USER10 SET DEFAULT_WAREHOUSE = DEFAULT; 357 | USE ROLE USERADMIN; 358 | DESC USER USER10; 359 | 360 | // Page 173 - See a list of users 361 | USE ROLE SECURITYADMIN; 362 | SHOW USERS; 363 | 364 | // Page 173 - Use the LIKE command 365 | USE ROLE SECURITYADMIN; 366 | SHOW USERS LIKE 'USER%'; 367 | 368 | // Page 174 - Drop a user 369 | USE ROLE USERADMIN; 370 | DROP USER USER10; 371 | 372 | // Page 175 - Edit User from the Web UI 373 | 374 | // Page 176 - Manage Roles from the Web UI 375 | 376 | // Page 179 - Code Cleanup 377 | USE ROLE SYSADMIN; 378 | DROP DATABASE DB1; 379 | DROP DATABASE DB2; 380 | SHOW DATABASES; 381 | DROP WAREHOUSE VW1_WH; DROP WAREHOUSE VW2_WH; DROP WAREHOUSE VW3_WH; 382 | SHOW WAREHOUSES; 383 | 384 | USE ROLE ACCOUNTADMIN; 385 | DROP RESOURCE MONITOR MONITOR1_RM; 386 | SHOW RESOURCE MONITORS; 387 | 388 | USE ROLE USERADMIN; 389 | DROP ROLE DATA_SCIENTIST; DROP ROLE ANALYST_SR; DROP ROLE ANALYST_JR; 390 | DROP ROLE DATA_EXCHANGE_ASST; DROP ROLE ACCOUNTANT_SR; DROP ROLE ACCOUNTANT_JR; 391 | DROP ROLE PRD_DBA; DROP ROLE DATA_ENGINEER; DROP ROLE DEVELOPER_SR; DROP 392 | ROLE DEVELOPER_JR; DROP ROLE LOADER; DROP ROLE VISUALIZER; DROP ROLE REPORTING; 393 | DROP ROLE MONITORING; DROP ROLE RM1_MODIFY; DROP ROLE WH1_USAGE; 394 | DROP ROLE WH2_USAGE; DROP ROLE WH3_USAGE; DROP ROLE DB1_MONITOR; DROP 395 | ROLE DB2_MONITOR; DROP ROLE WH1_MONITOR; DROP ROLE WH2_MONITOR; DROP ROLE 396 | WH3_MONITOR; DROP ROLE RM1_MONITOR; DROP ROLE DB1_SCHEMA1_READONLY; DROP ROLE 397 | DB1_SCHEMA1_ALL; DROP ROLE DB2_SCHEMA1_READONLY; DROP ROLE DB2_SCHEMA1_ALL; 398 | DROP ROLE DB2_SCHEMA2_READONLY; DROP ROLE DB2_SCHEMA2_ALL; 399 | SHOW ROLES; 400 | 401 | USE ROLE USERADMIN; 402 | DROP USER USER1; DROP USER USER2; DROP USER USER3;DROP USER USER4; 403 | 404 | USE ROLE SECURITYADMIN; 405 | SHOW USERS; 406 | -------------------------------------------------------------------------------- /Chapter Code/Chapter06.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 6: Data Loading and Unloading 6 | 7 | 8 | // Page 184 - Prep Work 9 | // Create new worksheet: Chapter 12 Workloads 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | // Page 184 - Prep Work 13 | USE ROLE SYSADMIN; 14 | USE WAREHOUSE COMPUTE_WH; 15 | CREATE OR REPLACE DATABASE DEMO6_DB 16 | COMMENT = "Database for all Chapter 6 Examples"; 17 | CREATE OR REPLACE SCHEMA WS COMMENT = "Schema for Worksheet Insert Examples"; 18 | CREATE OR REPLACE SCHEMA UI COMMENT = "Schema for Web UI Uploads"; 19 | CREATE OR REPLACE SCHEMA SNOW COMMENT = "Schema for SnowSQL Loads"; 20 | CREATE OR REPLACE WAREHOUSE LOAD_WH 21 | COMMENT = "Warehouse for CH 6 Load Examples"; 22 | 23 | 24 | // Page 192 - Create a new database and schema to be used for examples 25 | USE WAREHOUSE LOAD_WH; 26 | USE DATABASE DEMO6_DB; 27 | USE SCHEMA WS; 28 | 29 | // Page 193 - Create table for single-row inserts for structured data 30 | CREATE OR REPLACE TABLE TABLE1 31 | (id integer, f_name string, l_name string, city string) 32 | COMMENT = "Single-Row Insert for Structured Data 33 | using Explicitly Specified Values"; 34 | 35 | // Page 193 - Insert values into the table and confirm there is one row of data in the table 36 | INSERT INTO TABLE1 (id, f_name, l_name, city) 37 | VALUES (1, 'Anthony', 'Robinson', 'Atlanta'); 38 | SELECT * FROM TABLE1; 39 | 40 | // Page 193 - Insert another row and confirm 41 | INSERT INTO TABLE1 (id, f_name, l_name, city) 42 | VALUES (2, 'Peggy', 'Mathison', 'Birmingham'); 43 | SELECT * FROM TABLE1; 44 | 45 | // Page 193 - Create a table to be used for semi-structured datra 46 | CREATE OR REPLACE TABLE TABLE2 47 | (id integer, variant1 variant) 48 | COMMENT = "Single-Row Insert for Semi-Structured JSON Data"; 49 | 50 | // Page 193 - Use a query clause to insert values and confirm there is one row of data 51 | INSERT INTO TABLE2 (id, variant1) 52 | SELECT 1, parse_json(' {"f_name": "Anthony", "l_name": "Robinson", 53 | "city": "Atlanta" } '); 54 | SELECT * FROM TABLE2; 55 | 56 | // Page 193 - Insert another row of data 57 | INSERT INTO TABLE2 (id, variant1) 58 | SELECT 2, parse_json(' {"f_name": "Peggy", "l_name": "Mathison", 59 | "city": "Birmingham" } '); 60 | SELECT * FROM TABLE2; 61 | 62 | // Page 194 - Create a new table and insert two rows of data at one time 63 | CREATE OR REPLACE TABLE TABLE3 64 | (id integer, f_name string, l_name string, city string) 65 | COMMENT = "Multi-row Insert for Structured Data using Explicitly Stated Values"; 66 | INSERT INTO TABLE3 (id, f_name, l_name, city) VALUES 67 | (1, 'Anthony', 'Robinson', 'Atlanta'), (2, 'Peggy', 'Mathison', 68 | 'Birmingham'); 69 | SELECT * FROM TABLE3; 70 | 71 | // Page 194 - Create a new table and insert only specific records form an existing table 72 | CREATE OR REPLACE TABLE TABLE4 73 | (id integer, f_name string, l_name string, city string) 74 | COMMENT = "Multi-row Insert for Structured Data using Query, All Columns Same"; 75 | INSERT INTO TABLE4 (id, f_name, l_name, city) 76 | SELECT * FROM TABLE3 WHERE CONTAINS (city, 'Atlanta'); 77 | SELECT * FROM TABLE4; 78 | 79 | // Page 195 - Create a new table 80 | CREATE OR REPLACE TABLE TABLE5 81 | (id integer, f_name string, l_name string, city string) 82 | COMMENT = "Multi-row Insert for Structured Data using Query, Fewer Columns"; 83 | 84 | // Attempt to insert fewer column values in the new table than from the existing table without specifying columns 85 | // Error is expected 86 | INSERT INTO TABLE5 87 | (id, f_name, l_name) SELECT * FROM TABLE3 WHERE CONTAINS (city, 'Atlanta'); 88 | 89 | // Page 195 - Insert fewer column values in the new table than from the existing table 90 | INSERT INTO TABLE5 (id, f_name, l_name) 91 | SELECT id, f_name, l_name FROM TABLE3 WHERE CONTAINS (city, 'Atlanta'); 92 | SELECT * FROM TABLE5; 93 | 94 | // Page 196 - Create a table and insert values that will be used in next example 95 | CREATE OR REPLACE TABLE TABLE6 96 | (id integer, first_name string, last_name string, city_name string) 97 | COMMENT = "Table to be used as part of next demo"; 98 | 99 | INSERT INTO TABLE6 (id, first_name, last_name, city_name) VALUES 100 | (1, 'Anthony', 'Robinson', 'Atlanta'), 101 | (2, 'Peggy', 'Mathison', 'Birmingham'); 102 | 103 | // Page 196 - Create a new table and use CTE 104 | CREATE OR REPLACE TABLE TABLE7 105 | (id integer, f_name string, l_name string, city string) 106 | COMMENT = "Multi-row Insert for Structured Data using CTE"; 107 | 108 | INSERT INTO TABLE7 (id, f_name, l_name, city) 109 | WITH CTE AS 110 | (SELECT id, first_name as f_name, last_name as l_name, 111 | city_name as city FROM TABLE6) 112 | SELECT id, f_name, l_name, city 113 | FROM CTE; 114 | SELECT * FROM TABLE7; 115 | 116 | // Page 196 - Create a new table that will be used in next example 117 | CREATE OR REPLACE TABLE TABLE8 118 | (id integer, f_name string, l_name string, zip_code string) 119 | COMMENT = "Table to be used as part of next demo"; 120 | INSERT INTO TABLE8 (id, f_name, l_name, zip_code) 121 | VALUES (1, 'Anthony', 'Robinson', '30301'), (2, 'Peggy', 'Mathison', '35005'); 122 | 123 | // Page 196 - Create another table that will be used in the next example 124 | CREATE OR REPLACE TABLE TABLE9 125 | (id integer, zip_code string, city string, state string) 126 | COMMENT = "Table to be used as part of next demo"; 127 | INSERT INTO TABLE9 (id, zip_code, city, state) VALUES 128 | (1, '30301', 'Atlanta', 'Georgia'), 129 | (2, '35005', 'Birmingham', 'Alabama'); 130 | 131 | // Page 197 - Create a new table to use for inserting records using an ineer join 132 | CREATE OR REPLACE TABLE TABLE10 133 | (id integer, f_name string, l_name string, city string, 134 | state string, zip_code string) 135 | COMMENT = "Multi-row inserts from two tables using an Inner JOIN on zip_code"; 136 | 137 | INSERT INTO TABLE10 (id, f_name, l_name, city, state, zip_code) 138 | SELECT a.id, a.f_name, a.l_name, b.city, b.state, a.zip_code 139 | FROM TABLE8 a 140 | INNER JOIN TABLE9 b on a.zip_code = b.zip_code; 141 | SELECT *FROM TABLE10; 142 | 143 | // Page 197 - Create a new table to be used for semi-structured data 144 | CREATE OR REPLACE TABLE TABLE11 145 | (variant1 variant) 146 | COMMENT = "Multi-row Insert for Semi-structured JSON Data"; 147 | 148 | // Page 197 - Insert values into the table 149 | INSERT INTO TABLE11 150 | select parse_json(column1) 151 | from values 152 | ('{ "_id": "1", 153 | "name": { "first": "Anthony", "last": "Robinson" }, 154 | "company": "Pascal", 155 | "email": "anthony@pascal.com", 156 | "phone": "+1 (999) 444-2222"}'), 157 | ('{ "id": "2", 158 | "name": { "first": "Peggy", "last": "Mathison" }, 159 | "company": "Ada", 160 | "email": "Peggy@ada.com", 161 | "phone": "+1 (999) 555-3333"}'); 162 | SELECT * FROM TABLE11; 163 | 164 | // Page 198 - Create a source table and insert values 165 | CREATE OR REPLACE TABLE TABLE12 166 | (id integer, first_name string, last_name string, city_name string) 167 | COMMENT = "Source Table to be used as part of next demo for Unconditional Table 168 | Inserts"; 169 | INSERT INTO TABLE12 (id, first_name, last_name, city_name) VALUES 170 | (1, 'Anthony', 'Robinson', 'Atlanta'), (2, 'Peggy', 'Mathison', 'Birmingham'); 171 | 172 | // Page 198 - Create two target tables 173 | CREATE OR REPLACE TABLE TABLE13 174 | (id integer, f_name string, l_name string, city string) 175 | COMMENT = "Unconditional Table Insert - Destination Table 1 for unconditional 176 | multi-table insert"; 177 | 178 | CREATE OR REPLACE TABLE TABLE14 179 | (id integer, f_name string, l_name string, city string) 180 | COMMENT = "Unconditional Table Insert - Destination Table 2 for unconditional 181 | multi-table insert"; 182 | 183 | // Page `99 - Use data from Table 12 to insert into two tables -- one insertion for all data and another insertion for select values` 184 | INSERT ALL 185 | INTO TABLE13 186 | INTO TABLE13 (id, f_name, l_name, city) 187 | VALUES (id, last_name, first_name, default) 188 | INTO TABLE14 (id, f_name, l_name, city) 189 | INTO TABLE14 VALUES (id, city_name, last_name, first_name) 190 | SELECT id, first_name, last_name, city_name FROM TABLE12; 191 | 192 | // Page 199 - Look at data in Table13 193 | SELECT * FROM TABLE13; 194 | 195 | // Page 199 - Look at data in Table14 196 | SELECT * FROM TABLE14; 197 | 198 | // Page 199 - Create a source table for the next example and insert values 199 | CREATE OR REPLACE TABLE TABLE15 200 | (id integer, first_name string, last_name string, city_name string) 201 | COMMENT = "Source Table to be used as part of next demo for 202 | Conditional multi-table Insert"; 203 | INSERT INTO TABLE15 (id, first_name, last_name, city_name) 204 | VALUES 205 | (1, 'Anthony', 'Robinson', 'Atlanta'), 206 | (2, 'Peggy', 'Mathison', 'Birmingham'), 207 | (3, 'Marshall', 'Baker', 'Chicago'),(4, 'Kevin', 'Cline', 'Denver'), 208 | (5, 'Amy', 'Ranger', 'Everly'),(6, 'Andy', 'Murray', 'Fresno'); 209 | 210 | // Page 200 Create two target tables 211 | CREATE OR REPLACE TABLE TABLE16 212 | (id integer, f_name string, l_name string, city string) 213 | COMMENT = "Destination Table 1 for conditional multi-table insert"; 214 | 215 | CREATE OR REPLACE TABLE TABLE17 216 | (id integer, f_name string, l_name string, city string) 217 | COMMENT = "Destination Table 2 for conditional multi-table insert"; 218 | 219 | // Page 200 - Demonstration of a conditional multitable insert 220 | INSERT ALL 221 | WHEN id <5 THEN 222 | INTO TABLE16 223 | WHEN id <3 THEN 224 | INTO TABLE16 225 | INTO TABLE17 226 | WHEN id = 1 THEN 227 | INTO TABLE16 (id, f_name) VALUES (id, first_name) 228 | ELSE 229 | INTO TABLE17 230 | SELECT id, first_name, last_name, city_name FROM TABLE15; 231 | 232 | // Page 200 - Look at data in TABLE16 233 | SELECT * FROM TABLE16; 234 | 235 | // Page 201 - Look at data in TABLE17 236 | SELECT * FROM TABLE17; 237 | 238 | // Page 201 - Create a table to be used for the next example 239 | CREATE OR REPLACE TABLE TABLE18 240 | (Array variant) 241 | COMMENT = "Insert Array"; 242 | 243 | // Page 201 - Insert values into TABLE18 244 | INSERT INTO TABLE18 245 | SELECT ARRAY_INSERT(array_construct(0, 1, 2, 3), 4, 4); 246 | 247 | // Page 202 - See the data in TABLE18 248 | SELECT * FROM TABLE18; 249 | 250 | // Page 202 - Insert values in a different position 251 | INSERT INTO TABLE18 252 | SELECT ARRAY_INSERT(array_construct(0, 1, 2, 3), 7, 4); 253 | 254 | // Page 202 - See the data in TABLE18 255 | SELECT * FROM TABLE18; 256 | 257 | // Page 202 - Create a new table to be used for next example 258 | CREATE OR REPLACE TABLE TABLE19 259 | (Object variant) 260 | COMMENT = "Insert Object"; 261 | 262 | // Page 202 - Insert key-value pairs 263 | INSERT INTO TABLE19 264 | SELECT OBJECT_INSERT(OBJECT_CONSTRUCT('a', 1, 'b', 2, 'c', 3), 'd', 4); 265 | SELECT * FROM TABLE19; 266 | 267 | // Page 202 - Insert values with blank value and different types of null values 268 | INSERT INTO TABLE19 SELECT 269 | OBJECT_INSERT(object_construct('a', 1, 'b', 2, 'c', 3), 'd', ' '); 270 | INSERT INTO TABLE19 SELECT 271 | OBJECT_INSERT(object_construct('a', 1, 'b', 2, 'c', 3), 'd', 'null'); 272 | INSERT INTO TABLE19 SELECT 273 | OBJECT_INSERT(object_construct('a', 1, 'b', 2, 'c', 3), 'd', null); 274 | INSERT INTO TABLE19 SELECT 275 | OBJECT_INSERT(object_construct('a', 1, 'b', 2, 'c', 3), null, 'd'); 276 | SELECT * FROM TABLE19; 277 | 278 | // Page 204 - Review the table comments 279 | SHOW TABLES LIKE '%TABLE%'; 280 | 281 | // Page 205 - Create the table to be used for the next example 282 | USE SCHEMA UI; 283 | CREATE OR REPLACE TABLE TABLE20 284 | (id integer, f_name string, l_name string, city string) 285 | COMMENT = "Load Structured Data file via the Web UI wizard"; 286 | 287 | // Manually load data as described in the chapter 288 | 289 | // Page 210 - Confirm that the data was uploaded 290 | USE DATABASE DEMO6_DB; 291 | USE SCHEMA UI; 292 | SELECT * FROM TABLE20; 293 | 294 | // Page 210 Download and install SnowSQL as described in the chapter 295 | 296 | // Page 210 - Get signed into SnowSQL 297 | //c:\>snowsql -a dx58224.us-central1.gcp -u JKAVILA2022 298 | //Password: ********* 299 | 300 | 301 | // Page 210 - In SnowSQL -- Set context 302 | USE ROLE ACCOUNTADMIN; 303 | USE WAREHOUSE LOAD_WH; 304 | USE DATABASE DEMO6_DB; 305 | USE SCHEMA SNOW; 306 | 307 | // Page 211 -- In SnowSQL - Create a new table 308 | CREATE OR REPLACE TABLE TABLE20 (id integer, f_name string, l_name string, city string); 309 | 310 | // Page 211 -- In SnowSQL -- Load the CSV file into the table stage 311 | // Make sure to replace the location in the example with the location on your computer 312 | Put file:///users/joyce/documents/TABLE20.csv @"DEMO6_DB"."SNOW".%"TABLE20"; 313 | 314 | // Page 211 - In SnowSQL -- Use the COPY INTO command 315 | COPY INTO "TABLE20" FROM @"DEMO6_DB"."SNOW".%"TABLE20" file_format=(type=csv SKIP_HEADER=1); 316 | 317 | // Page 222 - Example of how to clone a table 318 | // Make sure you are back in the worksheet 319 | USE ROLE SYSADMIN; USE SCHEMA WS; 320 | CREATE TABLE DEMO_CLONE CLONE TABLE1; 321 | 322 | // Page 225 - Code Cleanup 323 | USE WAREHOUSE COMPUTE_WH; 324 | DROP DATABASE DEMO6_DB; 325 | DROP WAREHOUSE LOAD_WH; 326 | 327 | 328 | 329 | 330 | 331 | 332 | 333 | 334 | 335 | 336 | 337 | 338 | 339 | 340 | 341 | 342 | 343 | -------------------------------------------------------------------------------- /Chapter Code/Chapter07.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 7: Implementing Data Governance, Account Security, and Data Protection and Recovery 6 | 7 | 8 | // Page 228 - Prep Work 9 | // Create new worksheet: Chapter7 Security, Protection, and Data Recovery 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | // Page 229 - create a new user 13 | // Make sure to replace YOUREMAIL@EMAIL.COM with your own personal email address 14 | USE ROLE USERADMIN; 15 | CREATE OR REPLACE USER ADAM 16 | PASSWORD = '123' 17 | LOGIN_NAME=ADAM 18 | DISPLAY_NAME=ADAM 19 | EMAIL= ' YOUREMAIL@EMAIL.COM ' 20 | MUST_CHANGE_PASSWORD=TRUE; 21 | 22 | //Page 229 - Create Users to be used in later examples 23 | USE ROLE USERADMIN; 24 | CREATE OR REPLACE ROLE HR_ROLE; 25 | CREATE OR REPLACE ROLE AREA1_ROLE; 26 | CREATE OR REPLACE ROLE AREA2_ROLE; 27 | 28 | // Page 229 - Create some objects to be used in later examples 29 | USE ROLE SYSADMIN; 30 | USE WAREHOUSE COMPUTE_WH; 31 | CREATE OR REPLACE DATABASE DEMO7_DB; 32 | CREATE OR REPLACE SCHEMA TAG_LIBRARY; 33 | CREATE OR REPLACE SCHEMA HRDATA; 34 | CREATE OR REPLACE SCHEMA CH7DATA; 35 | CREATE OR REPLACE TABLE DEMO7_DB.CH7DATA.RATINGS 36 | (EMP_ID integer, RATING integer, DEPT_ID varchar, AREA integer); 37 | 38 | // Page 229 -- Insert some arbitrary data 39 | INSERT INTO DEMO7_DB.CH7DATA.RATINGS VALUES 40 | (1, 77, '100', 1), 41 | (2, 80, '100', 1), 42 | (3, 72, '101', 1), 43 | (4, 94, '200', 2), 44 | (5, 88, '300', 3), 45 | (6, 91, '400', 3); 46 | 47 | // Page 230 - Grant some permissions to roles 48 | USE ROLE SECURITYADMIN; 49 | GRANT USAGE ON WAREHOUSE COMPUTE_WH TO ROLE HR_ROLE; 50 | GRANT USAGE ON WAREHOUSE COMPUTE_WH TO ROLE AREA1_ROLE; 51 | GRANT USAGE ON WAREHOUSE COMPUTE_WH TO ROLE AREA2_ROLE; 52 | 53 | // Page 230 -- Grant roles usage on the objects 54 | GRANT USAGE ON DATABASE DEMO7_DB TO ROLE HR_ROLE; 55 | GRANT USAGE ON DATABASE DEMO7_DB TO ROLE AREA1_ROLE; 56 | GRANT USAGE ON DATABASE DEMO7_DB TO ROLE AREA2_ROLE; 57 | GRANT USAGE ON SCHEMA DEMO7_DB.CH7DATA TO ROLE HR_ROLE; 58 | GRANT USAGE ON SCHEMA DEMO7_DB.HRDATA TO ROLE HR_ROLE; 59 | GRANT USAGE ON SCHEMA DEMO7_DB.CH7DATA TO ROLE AREA1_ROLE; 60 | GRANT USAGE ON SCHEMA DEMO7_DB.CH7DATA TO ROLE AREA2_ROLE; 61 | GRANT SELECT ON ALL TABLES IN SCHEMA DEMO7_DB.CH7DATA TO ROLE HR_ROLE; 62 | GRANT SELECT ON ALL TABLES IN SCHEMA DEMO7_DB.CH7DATA TO ROLE AREA1_ROLE; 63 | GRANT SELECT ON ALL TABLES IN SCHEMA DEMO7_DB.CH7DATA TO ROLE AREA2_ROLE; 64 | 65 | // Page 230 - Assign three roles to the new user and assign two custom roles back to SYSADMIN 66 | GRANT ROLE HR_ROLE TO USER ADAM; 67 | GRANT ROLE AREA1_ROLE TO USER ADAM; 68 | GRANT ROLE AREA2_ROLE TO USER ADAM; 69 | GRANT ROLE AREA1_ROLE TO ROLE SYSADMIN; 70 | GRANT ROLE AREA2_ROLE TO ROLE SYSADMIN; 71 | 72 | // Page 230 - Grant future priviliges to the HR Role 73 | USE ROLE ACCOUNTADMIN; 74 | GRANT SELECT ON FUTURE TABLES IN SCHEMA DEMO7_DB.HRDATA TO ROLE HR_ROLE; 75 | GRANT INSERT ON FUTURE TABLES IN SCHEMA DEMO7_DB.HRDATA TO ROLE HR_ROLE; 76 | USE ROLE SYSADMIN; 77 | 78 | // Page 236 - Number of queries each user has run 79 | USE ROLE ACCOUNTADMIN; 80 | SELECT USER_NAME, COUNT(*) USES FROM SNOWFLAKE.ACCOUNT_USAGE.ACCESS_HISTORY 81 | GROUP BY USER_NAME ORDER BY USES DESC; 82 | 83 | // Page 236 - Most frequently used tables 84 | SELECT OBJ.VALUE:objectName::STRING TABLENAME, 85 | COUNT(*) USES FROM SNOWFLAKE.ACCOUNT_USAGE.ACCESS_HISTORY, 86 | TABLE(FLATTEN(BASE_OBJECTS_ACCESSED)) OBJ GROUP BY TABLENAME ORDER BY USES DESC; 87 | 88 | // Page 236 - What tables are being accessed, by whom, and how frequently 89 | SELECT OBJ.VALUE:objectName::string TABLENAME, USER_NAME, 90 | COUNT(*) USES FROM SNOWFLAKE.ACCOUNT_USAGE.ACCESS_HISTORY, 91 | TABLE(FLATTEN(BASE_OBJECTS_ACCESSED)) OBJ GROUP BY 1, 2 ORDER BY USES DESC; 92 | 93 | // Page 239 - Set the retention time for a database to 90 days 94 | USE ROLE SYSADMIN; 95 | ALTER DATABASE DEMO7_DB SET DATA_RETENTION_TIME_IN_DAYS = 90; 96 | 97 | // Page 240 - Confirm that a table in the database has 90-day retention time 98 | USE ROLE SYSADMIN; 99 | SELECT TABLE_CATALOG, TABLE_SCHEMA, TABLE_NAME, RETENTION_TIME 100 | FROM DEMO7_DB.INFORMATION_SCHEMA.TABLES; 101 | 102 | // Page 240 - Take a look at the Ratings table as it exists before making change 103 | SELECT * FROM DEMO7_DB.CH7DATA.RATINGS; 104 | 105 | // Page 240 - Change all areas to 4 even though intent was just to change one value 106 | USE ROLE SYSADMIN; 107 | UPDATE DEMO7_DB.CH7DATA.RATINGS AREA SET AREA=4; 108 | 109 | // Page 240 - Take a look at the Ratings table after the change was made 110 | SELECT * FROM DEMO7_DB.CH7DATA.RATINGS; 111 | 112 | // Page 241 - In order to use Time Travel to revert the table back to prior values, need to find out how far to travel back 113 | // Try 5 minutes first but may need to adjust to perhaps 2 or 3 minutes 114 | SELECT * FROM DEMO7_DB.CH7DATA.RATINGS at (offset => -60*5); 115 | 116 | // Page 241 - Use time travel to revert the table back to prior values before change was made 117 | // If changed value from 5 minutes to a different value in previous statement, use that new value 118 | CREATE OR REPLACE TABLE DEMO7_DB.CH7DATA.RATINGS 119 | AS SELECT * FROM DEMO7_DB.CH7DATA.RATINGS at (offset => -60*5); 120 | 121 | // Page 241 - Take a look at the Ratings table now 122 | SELECT * FROM DEMO7_DB.CH7DATA.RATINGS; 123 | 124 | // Page 241 - Drop a table 125 | DROP TABLE DEMO7_DB.CH7DATA.RATINGS; 126 | 127 | // Page 241 - Take a look at the Ratings table now 128 | // You'll see that the table no longer exists 129 | SELECT * FROM DEMO7_DB.CH7DATA.RATINGS; 130 | 131 | // Page 241 - Undrop the table 132 | UNDROP TABLE DEMO7_DB.CH7DATA.RATINGS; 133 | 134 | // Page 241 - Take a look at the Ratings table now 135 | // You'll see that the table does now exist 136 | SELECT * FROM DEMO7_DB.CH7DATA.RATINGS; 137 | 138 | // Page 243 - How much storage is attributable to each section 139 | USE ROLE ACCOUNTADMIN; 140 | SELECT TABLE_NAME,ACTIVE_BYTES,TIME_TRAVEL_BYTES,FAILSAFE_BYTES 141 | FROM SNOWFLAKE.ACCOUNT_USAGE.TABLE_STORAGE_METRICS; 142 | 143 | // Page 246 - Create a tag library, taxonomy of tags 144 | USE ROLE SYSADMIN; 145 | CREATE OR REPLACE SCHEMA DEMO7_DB.TAG_LIBRARY; 146 | 147 | // Page 246 - Create tag level Classification 148 | CREATE OR REPLACE TAG Classification; 149 | ALTER TAG Classification set comment = 150 | "Tag Tables or Views with one of the following classification values: 151 | 'Confidential', 'Restricted', 'Internal', 'Public'"; 152 | 153 | // Page 246 - Create tag level PII 154 | CREATE OR REPLACE TAG PII; 155 | ALTER TAG PII set comment = "Tag Tables or Views with PII with one or more 156 | of the following values: 'Phone', 'Email', 'Address'"; 157 | 158 | // Page 246 - Create tag level Sensitive PII 159 | CREATE OR REPLACE TAG SENSITIVE_PII; 160 | ALTER TAG SENSITIVE_PII set comment = "Tag Tables or Views with Sensitive PII 161 | with one or more of the following values: 'SSN', 'DL', 'Passport', 162 | 'Financial', 'Medical'"; 163 | 164 | // Page 247 - Create an Employees table and insert some values into it 165 | USE ROLE SYSADMIN; 166 | CREATE OR REPLACE TABLE DEMO7_DB.HRDATA.EMPLOYEES (emp_id integer, 167 | fname varchar(50), lname varchar(50), ssn varchar(50), email varchar(50), 168 | dept_id integer, dept varchar(50)); 169 | INSERT INTO DEMO7_DB.HRDATA.EMPLOYEES (emp_id, fname, lname, ssn, email, 170 | dept_id, dept) VALUES 171 | (0, 'First', 'Last', '000-00-0000', 'email@email.com', '100', 'IT'); 172 | 173 | 174 | // Page 247 - Assign a tag at the table level 175 | ALTER TABLE DEMO7_DB.HRDATA.EMPLOYEES 176 | set tag DEMO7_DB.TAG_LIBRARY.Classification="Confidential"; 177 | 178 | // Page 248 - Set tags at the column level 179 | ALTER TABLE DEMO7_DB.HRDATA.EMPLOYEES MODIFY EMAIL 180 | set tag DEMO7_DB.TAG_LIBRARY.PII = "Email"; 181 | ALTER TABLE DEMO7_DB.HRDATA.EMPLOYEES MODIFY SSN 182 | SET TAG DEMO7_DB.TAG_LIBRARY.SENSITIVE_PII = "SSN"; 183 | 184 | // Page 248 - Use the SHOW ocmmand to see the details of the tags 185 | SHOW TAGS; 186 | 187 | // Page 247 - See if a particular tag is associated wtih a specific table 188 | SELECT SYSTEM$GET_TAG('Classification', 'DEMO7_DB.HRDATA.EMPLOYEES', 'table'); 189 | 190 | // Page 248 - See if a particular tag is associated with a specific column 191 | SELECT SYSTEM$GET_TAG('SENSITIVE_PII', 'DEMO7_DB.HRDATA.EMPLOYEES.SSN', 192 | 'column'); 193 | 194 | // Page 248 - See if a particular tag is associated with a specific column 195 | SELECT SYSTEM$GET_TAG('SENSITIVE_PII', 'DEMO7_DB.HRDATA.EMPLOYEES.EMAIL', 196 | 'column'); 197 | 198 | 199 | // Page 248 Audit all columns with a sensitive tag without a masking policy 200 | // Note that Latency may be up to 2 hours for tag_references so you may need to revisit this statement later 201 | USE ROLE ACCOUNTADMIN; 202 | WITH column_with_tag 203 | AS (SELECT object_name table_name, 204 | column_name column_name, 205 | object_database db_name, 206 | object_schema schema_name 207 | FROM snowflake.account_usage.tag_references 208 | WHERE tag_schema='TAG_LIBRARY' 209 | AND (tag_name='SENSITIVE_PII' OR tag_name = 'PII') 210 | AND column_name is not null), 211 | column_with_policy 212 | AS (SELECT ref_entity_name table_name, 213 | ref_column_name column_name, 214 | ref_database_name db_name, 215 | ref_schema_name schema_name 216 | FROM snowflake.account_usage.policy_references 217 | WHERE policy_kind='MASKING POLICY') 218 | SELECT * 219 | FROM column_with_tag 220 | MINUS 221 | SELECT * 222 | FROM column_with_policy; 223 | 224 | // Page 251 - Create a masking policy 225 | USE ROLE ACCOUNTADMIN; 226 | CREATE OR REPLACE masking policy DEMO7_DB.HRDATA.emailmask 227 | AS (val string) returns string -> 228 | CASE WHEN current_role() in ('HR_ROLE') THEN val 229 | ELSE '**MASKED**' END; 230 | ALTER TABLE DEMO7_DB.HRDATA.EMPLOYEES modify column EMAIL 231 | set masking policy DEMO7_DB.HRDATA.emailmask; 232 | 233 | 234 | // Page 251 - Create another masking policy 235 | CREATE OR REPLACE masking policy DEMO7_DB.HRDATA.SSNmask 236 | AS (val string) returns string -> 237 | CASE WHEN current_role() in ('HR_ROLE') THEN val 238 | ELSE '**MASKED**' END; 239 | 240 | ALTER TABLE DEMO7_DB.HRDATA.EMPLOYEES modify column SSN 241 | set masking policy DEMO7_DB.HRDATA.SSNmask; 242 | 243 | // Page 252 - Notice what the ACCOUNTADMIN role sees 244 | USE ROLE ACCOUNTADMIN; 245 | SELECT * FROM DEMO7_DB.HRDATA.EMPLOYEES; 246 | 247 | // Page 252 - Notice what Be sure to log in as Adam 248 | USE ROLE HR_ROLE; 249 | USE WAREHOUSE COMPUTE_WH; 250 | SELECT * FROM DEMO7_DB.HRDATA.EMPLOYEES; 251 | 252 | // Page 252 - You should still be logged in as Adam 253 | INSERT INTO DEMO7_DB.HRDATA.EMPLOYEES (emp_id, fname, lname, ssn, email, dept_id, dept) VALUES 254 | (1, 'Harry', 'Smith', '111-11-1111', 'harry@coemail.com', '100', 'IT'), 255 | (2, 'Marsha', 'Addison', '222-22-2222', 'marsha@coemail.com', '100','IT'), 256 | (3, 'Javier', 'Sanchez', '333-33-3333', 'javier@coemail.com', '101', 'Marketing'), 257 | (4, 'Alicia', 'Rodriguez', '444-44-4444', 'alicia@coemail.com', '200', 'Finance'), 258 | (5, 'Marco', 'Anderson', '555-55-5555', 'marco@coemail.com', '300', 'HR'), 259 | (6, 'Barbara', 'Francis', '666-66-6666', 'barbara@coemail.com', '400', 'Exec'); 260 | SELECT * FROM DEMO7_DB.HRDATA.EMPLOYEES; 261 | 262 | 263 | // Page 253 - Make sure you are logged back in as yourself 264 | USE ROLE ACCOUNTADMIN; 265 | CREATE OR REPLACE masking policy DEMO7_DB.HRDATA.namemask 266 | AS (EMP_ID integer, DEPT_ID integer) returns integer -> 267 | CASE WHEN current_role() = 'HR_ROLE' 268 | then EMP_ID WHEN DEPT_ID = '100' 269 | then EMP_ID 270 | ELSE '**MASKED**' END; 271 | 272 | 273 | // Page 254 - Create a mapping table 274 | USE ROLE SYSADMIN; 275 | USE DATABASE DEMO7_DB; 276 | USE SCHEMA CH7DATA; 277 | CREATE OR REPLACE TABLE AreaFiltering (role_name text, area_id integer); 278 | INSERT INTO AreaFiltering (role_name, area_id) VALUES 279 | ('AREA1', 1), ('AREA2', 2); 280 | SELECT * FROM AreaFiltering; 281 | 282 | // Page 254 - Create a secure view 283 | USE ROLE SYSADMIN; 284 | CREATE OR REPLACE SECURE VIEW V_RATINGS_SUMMARY AS 285 | SELECT emp_id, rating, dept_id, area 286 | FROM RATINGS 287 | WHERE area= (SELECT area_id FROM AreaFiltering 288 | WHERE role_name=CURRENT_ROLE()); 289 | 290 | 291 | // Page 254 - Data can not be seen when using the SYSADMIN role, the current role being used 292 | SELECT * FROM v_ratings_summary; 293 | 294 | // Page 254 - Give AREA1_ROLE the ability to see data in the secure view 295 | GRANT SELECT ON ALL TABLES IN SCHEMA CH7DATA TO ROLE AREA1_ROLE; 296 | GRANT SELECT ON AreaFiltering TO ROLE AREA1_ROLE; 297 | GRANT SELECT ON v_ratings_summary TO ROLE AREA1_ROLE; 298 | 299 | // Page 254 - Be sure to log in as Adam 300 | USE ROLE AREA1_ROLE; 301 | USE DATABASE DEMO7_DB; 302 | USE SCHEMA CH7DATA; 303 | SELECT * FROM v_ratings_summary; 304 | 305 | // Page 255 - Log back in as yourself to run the next statement 306 | USE ROLE SYSADMIN; 307 | GRANT SELECT ON ALL TABLES IN SCHEMA CH7DATA TO ROLE AREA2_ROLE; 308 | GRANT SELECT ON AreaFiltering TO ROLE AREA2_ROLE; 309 | GRANT SELECT ON v_ratings_summary TO ROLE AREA2_ROLE; 310 | 311 | // Page 255 - Be sure to log in as Adam 312 | USE ROLE AREA2_ROLE; 313 | USE DATABASE DEMO7_DB; 314 | USE SCHEMA CH7DATA; 315 | SELECT * FROM v_ratings_summary; 316 | 317 | // Page 255 - Drop the secure view because we want to replace the original view with a secure view 318 | USE ROLE SYSADMIN; 319 | DROP VIEW v_ratings_summary; 320 | 321 | // Page 255 - Create a secure view that uses multicondition query 322 | USE ROLE SYSADMIN; 323 | USE DATABASE DEMO7_DB; 324 | USE SCHEMA CH7DATA; 325 | CREATE SECURE VIEW v_ratings_summary AS 326 | SELECT emp_id, rating, dept_id, area 327 | FROM RATINGS 328 | WHERE area IN (SELECT area_id FROM AreaFiltering 329 | WHERE role_name IN 330 | (SELECT value FROM TABLE(flatten(input => 331 | parse_json(CURRENT_AVAILABLE_ROLES())))) ); 332 | 333 | // Page 256 - Give necessary privileges to the roles 334 | GRANT SELECT ON AreaFiltering TO ROLE AREA1_ROLE; 335 | GRANT SELECT ON v_ratings_summary TO ROLE AREA1_ROLE; 336 | GRANT SELECT ON AreaFiltering TO ROLE AREA2_ROLE; 337 | GRANT SELECT ON v_ratings_summary TO ROLE AREA2_ROLE; 338 | 339 | // Page 256 - Log in as Adam 340 | USE ROLE AREA1_ROLE; 341 | USE DATABASE DEMO7_DB; 342 | USE SCHEMA CH7DATA; 343 | SELECT * FROM v_ratings_summary; 344 | 345 | // Page 256 - Make sure you are still logged in as Adam 346 | USE DATABASE DEMO7_DB; 347 | USE SCHEMA CH7DATA; 348 | SELECT * FROM v_ratings_summary; 349 | 350 | // Page 258 - Code Cleanup 351 | USE ROLE ACCOUNTADMIN; 352 | DROP DATABASE DEMO7_DB; 353 | DROP USER ADAM; -------------------------------------------------------------------------------- /Chapter Code/Chapter08.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 8: Managing Snowflake Account Costs 6 | 7 | 8 | // Page 262 - Prep Work 9 | // Create new worksheet: Chapter8 Managing Costs 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | // Page 262 - Create virtual warehouses to be used for resource monitor section 13 | USE ROLE SYSADMIN; 14 | USE WAREHOUSE COMPUTE_WH; 15 | CREATE OR REPLACE WAREHOUSE VW2_WH WITH WAREHOUSE_SIZE = MEDIUM 16 | AUTO_SUSPEND = 300 AUTO_RESUME = true, INITIALLY_SUSPENDED=true; 17 | CREATE OR REPLACE WAREHOUSE VW3_WH WITH WAREHOUSE_SIZE = SMALL 18 | AUTO_SUSPEND = 300 AUTO_RESUME = true, INITIALLY_SUSPENDED=true; 19 | CREATE OR REPLACE WAREHOUSE VW4_WH WITH WAREHOUSE_SIZE = MEDIUM 20 | AUTO_SUSPEND = 300 AUTO_RESUME = true, INITIALLY_SUSPENDED=true; 21 | CREATE OR REPLACE WAREHOUSE VW5_WH WITH WAREHOUSE_SIZE = SMALL 22 | AUTO_SUSPEND = 300 AUTO_RESUME = true, INITIALLY_SUSPENDED=true; 23 | CREATE OR REPLACE WAREHOUSE VW6_WH WITH WAREHOUSE_SIZE = MEDIUM 24 | AUTO_SUSPEND = 300 AUTO_RESUME = true, INITIALLY_SUSPENDED=true; 25 | 26 | // Page 262 - Use the Home icon to navigate to the Main Menu 27 | // Make sure your role is set to ACCOUNTADMIN 28 | 29 | // Page 263 - Navigate to Admin --> Usage 30 | 31 | // Page 272 - Create an account-level resource monitor 32 | // Make sure you have navigated back to the worksheet and that your role is set to ACCOUNTADMIN 33 | USE ROLE ACCOUNTADMIN; 34 | CREATE OR REPLACE RESOURCE MONITOR MONITOR1_RM WITH CREDIT_QUOTA = 5000 35 | TRIGGERS on 50 percent do notify 36 | on 75 percent do notify 37 | on 100 percent do notify 38 | on 110 percent do notify 39 | on 125 percent do notify; 40 | 41 | // Page 272 - Assing the account-level resource monitor to our account 42 | USE ROLE ACCOUNTADMIN; 43 | ALTER ACCOUNT SET RESOURCE_MONITOR = MONITOR1_RM; 44 | 45 | // Page 272 - Create a virtual warehouse-level monitor and assign it to the priority resource monitor 46 | USE ROLE ACCOUNTADMIN; 47 | CREATE OR REPLACE RESOURCE MONITOR MONITOR5_RM WITH CREDIT_QUOTA = 1500 48 | TRIGGERS on 50 percent do notify 49 | on 75 percent do notify 50 | on 100 percent do notify 51 | on 110 percent do notify 52 | on 125 percent do notify; 53 | ALTER WAREHOUSE VW2_WH SET RESOURCE_MONITOR = MONITOR5_RM; 54 | 55 | // Page 272 - Look at the resource monitors created thus far 56 | USE ROLE ACCOUNTADMIN; 57 | SHOW RESOURCE MONITORS; 58 | 59 | // Page 273 - Create another warehouse-level resource monitor 60 | USE ROLE ACCOUNTADMIN; 61 | CREATE OR REPLACE RESOURCE MONITOR MONITOR2_RM WITH CREDIT_QUOTA = 500 62 | TRIGGERS on 50 percent do notify 63 | on 75 percent do notify 64 | on 100 percent do notify 65 | on 100 percent do suspend 66 | on 110 percent do notify 67 | on 110 percent do suspend_immediate; 68 | ALTER WAREHOUSE VW3_WH SET RESOURCE_MONITOR = MONITOR2_RM; 69 | 70 | 71 | // Page 273 Create another resource monitor and assign it 72 | USE ROLE ACCOUNTADMIN; 73 | CREATE OR REPLACE RESOURCE MONITOR MONITOR6_RM WITH CREDIT_QUOTA = 500 74 | TRIGGERS on 50 percent do notify 75 | on 75 percent do notify 76 | on 100 percent do notify 77 | on 100 percent do suspend 78 | on 110 percent do notify 79 | on 110 percent do suspend_immediate; 80 | ALTER WAREHOUSE VW6_WH SET RESOURCE_MONITOR = MONITOR6_RM; 81 | 82 | 83 | // Create another resource monitor and assign it 84 | USE ROLE ACCOUNTADMIN; 85 | CREATE OR REPLACE RESOURCE MONITOR MONITOR4_RM WITH CREDIT_QUOTA = 500 86 | TRIGGERS on 50 percent do notify 87 | on 75 percent do notify 88 | on 100 percent do notify 89 | on 100 percent do suspend 90 | on 110 percent do notify 91 | on 110 percent do suspend_immediate; 92 | ALTER WAREHOUSE VW6_WH SET RESOURCE_MONITOR = MONITOR4_RM; 93 | 94 | // Page 274 - Look at the details for all resource monitors 95 | USE ROLE ACCOUNTADMIN; 96 | SHOW RESOURCE MONITORS; 97 | 98 | // Page 274 - Look at the details for all virtual warehouses 99 | USE ROLE ACCOUNTADMIN; 100 | SHOW WAREHOUSES; 101 | 102 | // Page 274 - Drop the resource monitor we created in error 103 | DROP RESOURCE MONITOR MONITOR6_RM; 104 | 105 | // Page 275 - Create the final resource monitor and assign to two virtual warehouses 106 | USE ROLE ACCOUNTADMIN; 107 | CREATE OR REPLACE RESOURCE MONITOR MONITOR3_RM WITH CREDIT_QUOTA = 1500 108 | TRIGGERS on 50 percent do notify 109 | on 75 percent do notify 110 | on 100 percent do notify 111 | on 100 percent do suspend 112 | on 110 percent do notify 113 | on 110 percent do suspend_immediate; 114 | ALTER WAREHOUSE VW4_WH SET RESOURCE_MONITOR = MONITOR3_RM; 115 | ALTER WAREHOUSE VW5_WH SET RESOURCE_MONITOR = MONITOR3_RM; 116 | 117 | // Page 275 - Look at the details for all resource monitors 118 | USE ROLE ACCOUNTADMIN; 119 | SHOW RESOURCE MONITORS; 120 | 121 | // Page 275 - Look at the details for all virtual warehouses 122 | SHOW WAREHOUSES; 123 | 124 | // Page 275 Get details about the virtual warehouse used in the last query 125 | // Make sure you have run the "SHOW WAREHOUSES;" statement just prior to running this code 126 | SELECT "name", "size" 127 | FROM TABLE (RESULT_SCAN(LAST_QUERY_ID())) 128 | WHERE "resource_monitor" = 'null'; 129 | 130 | // Page 277 - Provides details of virtual warehouse cost by start time, assuming $3 is the credit price 131 | USE ROLE ACCOUNTADMIN; 132 | SET CREDIT_PRICE = 3.00; 133 | USE DATABASE SNOWFLAKE; 134 | USE SCHEMA ACCOUNT_USAGE; 135 | SELECT WAREHOUSE_NAME, START_TIME, END_TIME, CREDITS_USED, 136 | ($CREDIT_PRICE*CREDITS_USED) AS DOLLARS_USED 137 | FROM SNOWFLAKE.ACCOUNT_USAGE.WAREHOUSE_METERING_HISTORY 138 | ORDER BY START_TIME DESC; 139 | 140 | // Page 277 - Provides details of virtual warehouses cost for past 30 days, assuming $3 is the credit price 141 | SELECT WAREHOUSE_NAME,SUM(CREDITS_USED_COMPUTE) 142 | AS CREDITS_USED_COMPUTE_30DAYS, 143 | ($CREDIT_PRICE*CREDITS_USED_COMPUTE_30DAYS) AS DOLLARS_USED_30DAYS 144 | FROM ACCOUNT_USAGE.WAREHOUSE_METERING_HISTORY 145 | WHERE START_TIME >= DATEADD(DAY, -30, CURRENT_TIMESTAMP()) 146 | GROUP BY 1 147 | ORDER BY 2 DESC; 148 | 149 | // Page 282 - Create roles for specific prod, dev, and test environments 150 | USE ROLE SECURITYADMIN; 151 | CREATE OR REPLACE ROLE PROD_ADMIN; 152 | CREATE OR REPLACE ROLE DEV_ADMIN; 153 | CREATE OR REPLACE ROLE QA_ADMIN; 154 | GRANT ROLE PROD_ADMIN TO ROLE SYSADMIN; 155 | GRANT ROLE DEV_ADMIN TO ROLE SYSADMIN; 156 | GRANT ROLE QA_ADMIN TO ROLE SYSADMIN; 157 | 158 | // Page 282 - Grant privileges to the new roles 159 | USE ROLE SYSADMIN; 160 | GRANT CREATE DATABASE ON ACCOUNT TO ROLE PROD_ADMIN; 161 | GRANT CREATE DATABASE ON ACCOUNT TO ROLE DEV_ADMIN; 162 | GRANT CREATE DATABASE ON ACCOUNT TO ROLE QA_ADMIN; 163 | 164 | // Page 282 - Rename virtual warehouses 165 | USE ROLE SYSADMIN; 166 | ALTER WAREHOUSE IF EXISTS VW2_WH RENAME TO WH_PROD; 167 | ALTER WAREHOUSE IF EXISTS VW3_WH RENAME TO WH_DEV; 168 | ALTER WAREHOUSE IF EXISTS VW4_WH RENAME TO WH_QA; 169 | SHOW WAREHOUSES; 170 | 171 | // Page 282 - Grant usage to the associates roles 172 | USE ROLE ACCOUNTADMIN; 173 | USE WAREHOUSE COMPUTE_WH; 174 | GRANT USAGE ON WAREHOUSE WH_PROD TO ROLE PROD_ADMIN; 175 | GRANT USAGE ON WAREHOUSE WH_DEV TO ROLE DEV_ADMIN; 176 | GRANT USAGE ON WAREHOUSE WH_QA TO ROLE QA_ADMIN; 177 | 178 | // Page 282 - Create prod database, schema, and table and grant usage to Prod Administrator Role 179 | USE ROLE PROD_ADMIN; USE WAREHOUSE WH_PROD; 180 | CREATE OR REPLACE DATABASE PROD_DB; 181 | CREATE OR REPLACE SCHEMA CH8_SCHEMA; 182 | CREATE OR REPLACE TABLE TABLE_A 183 | (Customer_Account int, Amount int, transaction_ts timestamp); 184 | GRANT USAGE ON DATABASE PROD_DB TO ROLE DEV_ADMIN; 185 | 186 | // Page 282 - Create a clone of dev dataabase and grant usage to QA Administrator Role 187 | USE ROLE DEV_ADMIN; 188 | USE WAREHOUSE WH_DEV; 189 | CREATE OR REPLACE DATABASE DEV_DB CLONE PROD_DB; 190 | GRANT USAGE ON DATABASE DEV_DB TO ROLE QA_ADMIN; 191 | 192 | // Page 283 - Create a clone of QA database and grant use to Prod Administrator Role 193 | USE ROLE QA_ADMIN; 194 | USE WAREHOUSE WH_QA; 195 | CREATE OR REPLACE DATABASE QA_DB CLONE DEV_DB; 196 | GRANT USAGE ON DATABASE QA_DB TO ROLE PROD_ADMIN; 197 | 198 | // Page 283 - Create a new development schema and a new table 199 | USE ROLE DEV_ADMIN; USE WAREHOUSE WH_DEV; USE DATABASE DEV_DB; 200 | CREATE OR REPLACE SCHEMA DEVELOPMENT; 201 | CREATE OR REPLACE TABLE TABLE_B 202 | (Vendor_Account int, Amount int, transaction_ts timestamp); 203 | GRANT USAGE ON SCHEMA DEVELOPMENT TO ROLE QA_ADMIN; 204 | GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA DEVELOPMENT TO ROLE QA_ADMIN; 205 | 206 | // Page 283 QA can conduct testing 207 | USE ROLE QA_ADMIN; USE WAREHOUSE WH_QA; USE DATABASE QA_DB; 208 | CREATE OR REPLACE SCHEMA TEST; 209 | CREATE OR REPLACE TABLE QA_DB.TEST.TABLE_B 210 | AS SELECT * FROM DEV_DB.DEVELOPMENT.TABLE_B; 211 | GRANT USAGE ON SCHEMA TEST TO ROLE PROD_ADMIN; 212 | GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA TEST TO ROLE PROD_ADMIN; 213 | 214 | // Page 283 - Prod Admin can now copy the table into production 215 | USE ROLE PROD_ADMIN; 216 | USE WAREHOUSE WH_PROD; 217 | USE DATABASE PROD_DB; 218 | USE SCHEMA CH8_SCHEMA; 219 | CREATE OR REPLACE TABLE TABLE_B AS SELECT * FROM QA_DB.TEST.TABLE_B; 220 | 221 | // Page 284 Code Cleanup 222 | USE ROLE ACCOUNTADMIN; 223 | DROP DATABASE DEV_DB; DROP DATABASE PROD_DB; DROP DATABASE QA_DB; 224 | DROP ROLE PROD_ADMIN; DROP ROLE DEV_ADMIN; DROP ROLE QA_ADMIN; 225 | 226 | DROP RESOURCE MONITOR MONITOR1_RM; DROP RESOURCE MONITOR MONITOR2_RM; 227 | DROP RESOURCE MONITOR MONITOR3_RM; DROP RESOURCE MONITOR MONITOR4_RM; 228 | DROP RESOURCE MONITOR MONITOR5_RM; 229 | 230 | DROP WAREHOUSE WH_PROD; DROP WAREHOUSE WH_DEV; DROP WAREHOUSE WH_QA; 231 | DROP WAREHOUSE VW5_WH; DROP WAREHOUSE VW6_WH; 232 | 233 | 234 | -------------------------------------------------------------------------------- /Chapter Code/Chapter09.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 9: Analyzing and Improving Snowflake Query Performance 6 | 7 | 8 | // Page 287 - Prep Work 9 | // Create new worksheet: Chapter9 Improving Queries 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | 12 | 13 | // Page 288 - Returns details about all queries run by the current user in the past day 14 | // Make sure your role is set to ACCOUNTADMIN and make sure you replace with the name of the database you want to query 15 | USE ROLE ACCOUNTADMIN; 16 | USE DATABASE ; 17 | SELECT * 18 | FROM TABLE(INFORMATION_SCHEMA.QUERY_HISTORY( 19 | dateadd('days', -1, current_timestamp()), 20 | current_timestamp())) 21 | ORDER BY TOTAL_ELAPSED_TIME DESC; 22 | 23 | 24 | // Page 288 - Returns information about the queries executed for a particular database, in order of frquency and avg compilation time 25 | // Make sure your role is set to ACCOUNTADMIN and make sure you replace with the name of the database you want to query 26 | USE ROLE ACCOUNTADMIN; 27 | USE DATABASE ; 28 | SELECT HASH(query_text), QUERY_TEXT, COUNT(*), 29 | AVG(compilation_time), AVG(execution_time) 30 | FROM TABLE(INFORMATION_SCHEMA.QUERY_HISTORY(dateadd('days', -1, 31 | current_timestamp()),current_timestamp() ) ) 32 | GROUP BY HASH(query_text), QUERY_TEXT 33 | ORDER BY COUNT(*) DESC, AVG(compilation_time) DESC ; 34 | 35 | // Page 302 - Looks at the clustering information for a specific column 36 | USE ROLE ACCOUNTADMIN; 37 | USE DATABASE SNOWFLAKE_SAMPLE_DATA; 38 | USE SCHEMA TPCH_SF100; 39 | SELECT SYSTEM$CLUSTERING_INFORMATION( 'CUSTOMER' , '(C_NATIONKEY )' ); 40 | 41 | // Page 303 - Get the distinct count of values as well as total number of records 42 | USE ROLE ACCOUNTADMIN; 43 | USE DATABASE SNOWFLAKE_SAMPLE_DATA; 44 | USE SCHEMA TPCH_SF100; 45 | 46 | SELECT COUNT(DISTINCT C_NATIONKEY) FROM CUSTOMER; 47 | 48 | SELECT COUNT(C_NATIONKEY) FROM CUSTOMER; 49 | 50 | // Page 303 - Calculate the selectivity 51 | USE ROLE ACCOUNTADMIN; 52 | USE DATABASE SNOWFLAKE_SAMPLE_DATA; 53 | USE SCHEMA TPCH_SF100; 54 | SELECT COUNT(DISTINCT C_NATIONKEY) / Count(C_NATIONKEY) FROM CUSTOMER; 55 | 56 | // Page 304 - Look at the data distribution as part of considering whether column would be a good candidate for clustering key 57 | SELECT C_NATIONKEY, count(*) FROM CUSTOMER group by C_NATIONKEY; 58 | 59 | // Page 305 - Calculate the selectivity 60 | USE ROLE ACCOUNTADMIN; 61 | USE DATABASE SNOWFLAKE_SAMPLE_DATA; 62 | USE SCHEMA TPCH_SF100; 63 | SELECT COUNT(DISTINCT C_NAME) / Count(C_NAME) FROM CUSTOMER; 64 | 65 | // Page 305 - Define a clustering key at the time of table creation 66 | // Be sure to replace table name and column name text with an actual table and column 67 | ALTER TABLE CLUSTER BY (column name(s)); 68 | 69 | // Page 309 - Add search optimization to a table 70 | // Be sure to replace the table name text with an actual table 71 | ALTER TABLE [IF EXISTS]
ADD SEARCH OPTIMIZATION; 72 | 73 | // Page 310 - Code Cleanup 74 | // No cleanup needed since we used the sample database. -------------------------------------------------------------------------------- /Chapter Code/Chapter10.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 10: Configuring and Managing Secure Data Sharing 6 | 7 | 8 | // Page 317 - Prep Work 9 | // Create new worksheet: Chapter10 Data Sharing 10 | // Context setting - make sure role is set to ACCOUNTADMIN and COMPUTE_WH is the virtual warehouse 11 | USE ROLE ACCOUNTADMIN; 12 | USE WAREHOUSE COMPUTE_WH; 13 | CREATE OR REPLACE DATABASE DEMO10_DB; 14 | USE SCHEMA DEMO10_DB.PUBLIC; 15 | CREATE OR REPLACE TABLE SHARINGDATA (i integer); 16 | 17 | // Note -- This file contains the code to be executed in the worksheet 18 | // There are lots of things done in the web UI for this chapter; you can follow the instructions in the book, using the screenshots as your guide 19 | 20 | 21 | // Page 322 - Create a new share and grant usage on objects 22 | USE ROLE ACCOUNTADMIN; 23 | CREATE OR REPLACE SHARE DEMO10_SHARE2; 24 | GRANT USAGE ON DATABASE DEMO10_DB TO SHARE DEMO10_SHARE2; 25 | GRANT USAGE ON SCHEMA DEMO10_DB.PUBLIC TO SHARE DEMO10_SHARE2; 26 | GRANT SELECT ON TABLE DEMO10_DB.PUBLIC.SHARINGDATA TO SHARE DEMO10_SHARE2; 27 | 28 | // Page 324 - For use in a later example, create database, schema, and table and insert values 29 | USE ROLE ACCOUNTADMIN; 30 | USE DATABASE DEMO10_DB; 31 | CREATE OR REPLACE SCHEMA PRIVATE; 32 | CREATE OR REPLACE TABLE DEMO10_DB.PRIVATE.SENSITIVE_DATA 33 | (nation string, 34 | price float, 35 | size int, 36 | id string); 37 | INSERT INTO DEMO10_DB.PRIVATE.SENSITIVE_DATA 38 | values('USA', 123.5, 10,'REGION1'), 39 | ('USA', 89.2, 14, 'REGION1'), 40 | ('CAN', 99.0, 35, 'REGION2'), 41 | ('CAN', 58.0, 22, 'REGION2'), 42 | ('MEX', 112.6,18, 'REGION2'), 43 | ('MEX', 144.2,15, 'REGION2'), 44 | ('IRE', 96.8, 22, 'REGION3'), 45 | ('IRE', 107.4,19, 'REGION3'); 46 | 47 | // Page 324 - Create a table that will hold the mapping to individual accounts 48 | CREATE OR REPLACE TABLE DEMO10_DB.PRIVATE.SHARING_ACCESS 49 | (id string,snowflake_account string); 50 | 51 | // Page 324 - Give current account access to REGION1 data 52 | INSERT INTO SHARING_ACCESS values('REGION1', current_account()); 53 | 54 | 55 | // Page 325 - Assign REGION2 and REGION3 the values associated with their respective accounts 56 | INSERT INTO SHARING_ACCESS values('REGION2', 'ACCT2'); 57 | INSERT INTO SHARING_ACCESS values('REGION3', 'ACCT3'); 58 | SELECT * FROM SHARING_ACCESS; 59 | 60 | 61 | // Page 325 - Join data in base table with mapping table 62 | CREATE OR REPLACE SECURE VIEW DEMO10_DB.PUBLIC.PAID_SENSITIVE_DATA as 63 | SELECT nation, price, size 64 | FROM DEMO10_DB.PRIVATE.SENSITIVE_DATA sd 65 | JOIN DEMO10_DB.PRIVATE.SHARING_ACCESS sa on sd.id = sa.id 66 | AND sa.snowflake_account = current_account(); 67 | 68 | // Page 325 - Grant SELECT privilege to all roles 69 | GRANT SELECT ON DEMO10_DB.PUBLIC.PAID_SENSITIVE_DATA to PUBLIC; 70 | 71 | // Page 325 - Look at the data in the Private Sensitive Data table 72 | SELECT * FROM DEMO10_DB.PRIVATE.SENSITIVE_DATA; 73 | 74 | // Page 326 - Look at the data in the Public Sensitive Data table 75 | SELECT * FROM DEMO10_DB.PUBLIC.PAID_SENSITIVE_DATA; 76 | 77 | // Page 326 - Use a session variable 78 | ALTER SESSION SET simulated_data_sharing_consumer='ACCT2'; 79 | SELECT * FROM DEMO10_DB.PUBLIC.PAID_SENSITIVE_DATA; 80 | 81 | // Page 327 - Use another session variable 82 | ALTER SESSION SET simulated_data_sharing_consumer='ACCT3'; 83 | SELECT * FROM DEMO10_DB.PUBLIC.PAID_SENSITIVE_DATA; 84 | 85 | // Page 327 - Return our Snowflake account to its original account value 86 | ALTER SESSION UNSET simulated_data_sharing_consumer; 87 | 88 | // Page 327 - Create a new share 89 | USE ROLE ACCOUNTADMIN; 90 | USE DATABASE DEMO10_DB; 91 | USE SCHEMA DEMO10_DB.PUBLIC; 92 | CREATE OR REPLACE SHARE NATIONS_SHARED; 93 | SHOW SHARES; 94 | 95 | // Page 327 - Grant privileges to the new share 96 | GRANT USAGE ON DATABASE DEMO10_DB TO SHARE NATIONS_SHARED; 97 | GRANT USAGE ON SCHEMA DEMO10_DB.PUBLIC TO SHARE NATIONS_SHARED; 98 | GRANT SELECT ON DEMO10_DB.PUBLIC.PAID_SENSITIVE_DATA TO SHARE NATIONS_SHARED; 99 | 100 | // Page 327 - Use SHOW command to confirm contents of the share 101 | SHOW GRANTS TO SHARE NATIONS_SHARED; 102 | 103 | // Page 328 - How to add accounts 104 | // In production, you'd need to replace ACCT2 and ACCT4 with actual Snowflake account details 105 | ALTER SHARE NATIONS_SHARED ADD ACCOUNTS = ACCT2, ACCT3; 106 | 107 | // Page 328 - Use SHOW command to retrieve list of all Snowflake consumer accounts that have a database created from a share 108 | SHOW GRANTS OF SHARE NATIONS_SHARED; 109 | 110 | // Page 345 Code Cleanup 111 | // Error Expected 112 | USE ROLE ACCOUNTADMIN; 113 | DROP DATABASE DEMO10_DB; 114 | 115 | // Page 345 - Code Cleanup 116 | REVOKE USAGE ON DATABASE DEMO10_DB FROM SHARE NATIONS_SHARED; 117 | REVOKE USAGE ON DATABASE DEMO10_DB FROM SHARE DEMO10_SHARE; 118 | REVOKE USAGE ON DATABASE DEMO10_DB FROM SHARE DEMO10_SHARE2; 119 | DROP DATABASE DEMO10_DB; -------------------------------------------------------------------------------- /Chapter Code/Chapter11.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 11: Visualizing Data in Snowsight 6 | 7 | 8 | // Page 347 - Prep Work 9 | // Create new folder: Chapter 11 10 | // Create new worksheet: Chapter11 Visualization 11 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 12 | 13 | // Page 349 - Set Context 14 | USE ROLE SYSADMIN; 15 | USE DATABASE SNOWFLAKE_SAMPLE_DATA; 16 | USE SCHEMA TPCDS_SF100TCL; 17 | 18 | // Page 349 - There are some examples / instructions that refer to the Snowsight Web UI. You can find those in the textbook, including screenshots 19 | 20 | // Page 352 - Retrieve 100 records from the table 21 | SELECT * FROM STORE_SALES LIMIT 100; 22 | 23 | // Page 353 - Retrieve 100 records from the table by using SAMPLE 24 | SELECT * FROM STORE_SALES SAMPLE (100 ROWS); 25 | 26 | // Page 353 - Retrieve 100 records from the table by using TABLESAMPLE 27 | SELECT * FROM STORE_SALES TABLESAMPLE SYSTEM (0.015); 28 | 29 | // Page 354 - Retrieve 5000000 records 30 | SELECT * FROM CATALOG_RETURNS LIMIT 5000000; 31 | 32 | // Page 354 - Retrieve 9999 records 33 | SELECT * FROM CATALOG_RETURNS LIMIT 9999; 34 | 35 | // Several exercises are to be done in the web UI, as described in the book 36 | 37 | // Page 369 - Code Cleanup 38 | // No cleanup is needed -------------------------------------------------------------------------------- /Chapter Code/Chapter12.sql: -------------------------------------------------------------------------------- 1 | // Snowflake Definitive Guide 1st Edition by Joyce Kay Avila - August 2022 2 | // ISBN-10 : 1098103823 3 | // ISBN-13 : 978-1098103828 4 | // Contact the author: https://www.linkedin.com/in/joycekayavila/ 5 | // Chapter 12: Workloads for the Snowflake Data Cloud 6 | 7 | 8 | // Page 372 - Prep Work 9 | // Create new worksheet: Chapter 12 Workloads 10 | // Context setting - make sure role is set to SYSADMIN and COMPUTE_WH is the virtual warehouse 11 | USE ROLE SYSADMIN; 12 | USE WAREHOUSE COMPUTE_WH; 13 | CREATE OR REPLACE DATABASE DEMO12_DB; 14 | CREATE OR REPLACE SCHEMA CYBERSECURITY; 15 | ALTER SESSION SET USE_CACHED_RESULT = FALSE; 16 | 17 | // Page 392 - Create a base table 18 | CREATE OR REPLACE TABLE BASETABLE AS 19 | SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF100.LINEITEM; 20 | 21 | // Page 392 - Clone the table for use in the clustering example and then enable clustering 22 | CREATE OR REPLACE TABLE CLUSTEREXAMPLE CLONE BASETABLE; 23 | ALTER TABLE CLUSTEREXAMPLE CLUSTER BY (L_SHIPDATE); 24 | 25 | // Page 392 - Verify that the clustering is complete 26 | SELECT SYSTEM$CLUSTERING_INFORMATION('CLUSTEREXAMPLE','(L_SHIPDATE)'); 27 | 28 | // Page 393 - Compare the results to the unclustered base table 29 | SELECT SYSTEM$CLUSTERING_INFORMATION('BASETABLE','(L_SHIPDATE)'); 30 | 31 | // Page 394 - Clone the table and add Search Optimization 32 | CREATE OR REPLACE TABLE OPTIMIZEEXAMPLE CLONE BASETABLE; 33 | ALTER TABLE OPTIMIZEEXAMPLE ADD SEARCH OPTIMIZATION; 34 | 35 | // Page 394 - Use the SHOW command to see the details 36 | SHOW TABLES LIKE '%EXAMPLE%'; 37 | 38 | // Page 395 - Get an example of a record to be used later for the point lookup query 39 | SELECT * FROM BASETABLE 40 | LIMIT 1; 41 | 42 | // Page 396 - Use the previous L_ORDERKEY result value in this query 43 | SELECT * FROM BASETABLE WHERE L_ORDERKEY ='363617027'; 44 | 45 | // Page 396 - Use the same L_ORDERKEY result value in this query 46 | SELECT * FROM CLUSTEREXAMPLE WHERE L_ORDERKEY ='363617027'; 47 | 48 | // Page 397 - Use the range of dates from the previous search 49 | SELECT * FROM CLUSTEREXAMPLE 50 | WHERE L_SHIPDATE >= '1992-12-05'and L_SHIPDATE <='1993-02-20' 51 | AND L_ORDERKEY = '363617027'; 52 | 53 | // Page 399 - Use the L_ORDERKEY result value 54 | SELECT * FROM OPTIMIZEEXAMPLE WHERE L_ORDERKEY ='363617027'; 55 | 56 | // Page 400 - Run the query again now that some time has passed 57 | SELECT SYSTEM$CLUSTERING_INFORMATION('CLUSTEREXAMPLE','(L_SHIPDATE)'); 58 | 59 | // Page 403 - Code Cleanup 60 | DROP DATABASE DEMO12_DB; 61 | ALTER SESSION SET USE_CACHED_RESULT = TRUE; 62 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Snowflake Definitive Guide 1st Edition 2 | 3 | ### Author: [Joyce Kay Avila](https://www.linkedin.com/in/joycekayavila/) 4 | 5 | 6 |
7 | 8 | ### This repository includes the source code collection and supplemental material for the O'Reilly *Snowflake Definitive Guide* 1st Edition book (August 2022). 9 | 10 | • ISBN-10 : 1098103823
11 | • ISBN-13 : 978-1098103828 12 | 13 | 14 | ### The book can be purchased online at: 15 | • [O'Reilly](https://oreil.ly/PRJ83)
16 | • [Amazon](https://www.amazon.com/Snowflake-Definitive-Architecting-Designing-Deploying/dp/1098103823)
17 | • [Your favorite bookseller](https://bookshop.org/books/snowflake-the-definitive-guide-architecting-designing-and-deploying-on-the-snowflake-data-cloud/9781098103828) 18 | 19 | #### The book is also available at your local [Barnes & Noble](https://www.barnesandnoble.com/w/snowflake-joyce-avila/1141119692) bookstore and other independent bookstores around the world. 20 | 21 | #### The Snowflake Definitive Guide can now be [purchased in India](https://www.shroffpublishers.com/books/9789355421746/) 22 | 23 |
24 |
25 |
26 |
27 | 28 | Using Code Examples 29 | --- 30 | The book is intended to help you get your job done. In general, if example code is offered here on Github, you may use it in your programs and documentation. You do not need to contact the author or publisher for permission unless you’re reproducing a significant portion of the code. 31 | 32 | Selling or distributing examples from this Github does require permission. Incorporating a significant amount of example code from this book into your product’s documentation does require permission. 33 | 34 | Answering a question by citing this book and quoting example code does not require permission. 35 | 36 | Attribution is appreciated, but not required. An attribution usually includes the title, author, publisher, and ISBN. For example: “*Snowflake: The Definitive Guide* by Joyce Kay Avila (O’Reilly). Copyright 2022 Joyce Kay Avila, 978-1-098-10382-8.” 37 | -------------------------------------------------------------------------------- /Supplemental Material/DataVault Tutoral Reference Diagram.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/SnowflakeDefinitiveGuide/1st-Edition/2b50b754985b0bffb580caaf5a591df94f60b248/Supplemental Material/DataVault Tutoral Reference Diagram.png -------------------------------------------------------------------------------- /Supplemental Material/DataVault Tutorial Code.sql: -------------------------------------------------------------------------------- 1 | //Youtube Video: 2 | 3 | --My Youtube Channel: youtube.com/c/joycekayavila 4 | 5 | --Link to the specific video associated with this tutorial: https://youtu.be/zb89rvl4_Xs 6 | 7 | 8 | 9 | ----------------------------------------------------------------------------------- 10 | ----------------------------------------------------------------------------------- 11 | ----------------------------------------------------------------------------------- 12 | 13 | //PREWORK - ENVIRONMENT SETUP 14 | 15 | //Let's set the context for this worksheet 16 | //Note: for simplicity, the ACCOUNTADMIN role will be used for this tutorial. 17 | --but this would not likely be the case in a real production environment. 18 | USE ROLE ACCOUNTADMIN; 19 | USE WAREHOUSE COMPUTE_WH; 20 | 21 | //At the time of this tutorial, there were 15 million records in this table 22 | SELECT COUNT(1) FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.ORDERS; 23 | 24 | //At the time of this tutorial, there were 1.5 million records in this table 25 | SELECT COUNT(1) FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.CUSTOMER; 26 | 27 | //Create two virtual warehouses, one for generic use 28 | --and the other for use in the raw data layer for data pipelines. 29 | 30 | //Note: To make it easy to go back to any section of the tutorial, 31 | --we'll use the 'CREATE OR REPLACE' command to create new objects. 32 | --The 'CREATE OR REPLACE' command is not recommended for common use in the production environment. 33 | 34 | //Note: We are creating two new virtual warehouses but you can create as many virtual warehouses, 35 | --in varying sizes and configurations, that you need. 36 | 37 | //Tip: You may want to consider creating separate virtual warehouses for different layers 38 | --in the Data Vault architecture such as DV_BDV_WH and DV_INFO_WH 39 | 40 | CREATE OR REPLACE WAREHOUSE DV_GENERIC_WH 41 | WITH WAREHOUSE_SIZE = 'XSMALL' AUTO_SUSPEND = 300 AUTO_RESUME = TRUE INITIALLY_SUSPENDED = TRUE; 42 | CREATE OR REPLACE WAREHOUSE DV_RDV_WH 43 | WITH WAREHOUSE_SIZE = 'XSMALL' AUTO_SUSPEND = 300 AUTO_RESUME = TRUE INITIALLY_SUSPENDED = TRUE; 44 | 45 | //Use the new Generic virtual warehouse now for the tutorial 46 | USE WAREHOUSE DV_GENERIC_WH; 47 | 48 | //Create new Snowflake database and schemas to be used in the tutorial 49 | CREATE OR REPLACE DATABASE DV_TUTORIAL; 50 | CREATE OR REPLACE SCHEMA L00_STG COMMENT = 'Schema for Staging Area objects'; 51 | CREATE OR REPLACE SCHEMA L10_RDV COMMENT = 'Schema for Raw Data Vault objects'; 52 | CREATE OR REPLACE SCHEMA L20_BDV COMMENT = 'Schema for Business Data Vault objects'; 53 | CREATE OR REPLACE SCHEMA L30_INFO COMMENT = 'Schema for Information Delivery objects'; 54 | 55 | 56 | ----------------------------------------------------------------------------------- 57 | ----------------------------------------------------------------------------------- 58 | ----------------------------------------------------------------------------------- 59 | 60 | 61 | //STAGING AREA SETUP - NATION & REGION 62 | 63 | //Set Context. Use the schema for Staging area objects - L00.STG 64 | USE SCHEMA L00_STG; 65 | 66 | //Create two new staging tables for static reference data 67 | --LDTS = Load Data Timestamp 68 | --RSCR = Reference Source (Static Reference Data) 69 | 70 | //Create Nation Stage Table 71 | CREATE OR REPLACE TABLE STG_NATION 72 | AS 73 | SELECT SRC.*, 74 | CURRENT_TIMESTAMP() LDTS, 75 | 'STATIC REFERENCE DATA' RSCR 76 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.NATION SRC; 77 | 78 | //Validate 79 | SELECT * FROM STG_NATION; 80 | 81 | //Create Region Table 82 | CREATE OR REPLACE TABLE STG_REGION 83 | AS 84 | SELECT SRC.*, 85 | CURRENT_TIMESTAMP() LDTS, 86 | 'STATIC REFERENCE DATA' RSCR 87 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.REGION SRC; 88 | 89 | //Validate 90 | SELECT * FROM STG_REGION; 91 | 92 | //STAGING AREA SETUP - CUSTOMER & ORDER 93 | 94 | //Create two new tables to be used by Snowpipe to 95 | --drip-feed the data as it lands in the stage 96 | 97 | //Note that the full payload of JSON data will be loaded into the raw_json 98 | --column. We'll use the special VARIANT data type for this use case 99 | 100 | //Note that we'll also add some columns for metadata like 101 | --load data timestamp (ldts) and file row number 102 | 103 | //Create the Customer Stage Table 104 | CREATE OR REPLACE TABLE STG_CUSTOMER 105 | (RAW_JSON VARIANT, 106 | FILENAME STRING NOT NULL, 107 | FILE_ROW_SEQ NUMBER NOT NULL, 108 | LDTS STRING NOT NULL, 109 | RSCR STRING NOT NULL); 110 | 111 | //No records yet entered so query produces no results 112 | SELECT * FROM STG_CUSTOMER; 113 | 114 | //Create the ORDER Stage Table 115 | CREATE OR REPLACE TABLE STG_ORDER 116 | (O_ORDERKEY NUMBER, 117 | O_CUSTKEY NUMBER, 118 | O_ORDERSTATUS STRING, 119 | O_TOTALPRICE NUMBER, 120 | O_ORDERDATE DATE, 121 | O_ORDERPRIORITY STRING, 122 | O_CLERK STRING, 123 | O_SHIPPRIORITY NUMBER, 124 | O_COMMENT STRING, 125 | FILENAME STRING NOT NULL, 126 | FILE_ROW_SEQ NUMBER NOT NULL, 127 | LDTS STRING NOT NULL, 128 | RSCR STRING NOT NULL); 129 | 130 | //No records yet entered so query produces no results 131 | SELECT * FROM STG_ORDER; 132 | 133 | //STAGING AREA SETUP - STREAMS 134 | 135 | //Create streams on the staging tables in order to easily detect and 136 | --incrementally process the new portion of data 137 | CREATE OR REPLACE STREAM STG_CUSTOMER_STRM ON TABLE STG_CUSTOMER; 138 | CREATE OR REPLACE STREAM STG_ORDER_STRM ON TABLE STG_ORDER; 139 | 140 | 141 | //STAGING AREA SETUP - SAMPLE DATA 142 | 143 | 144 | //We'll be producing sample data by unloading a subset of data from the TPCH sample dataset then use Snowpipe to load it back 145 | --into the Data Vault tutorial, simulating the streaming feed. 146 | 147 | //Every Snowflake account provides access to sample data sets. You can find corresponding schemas in SNOWFLAKE_SAMPLE_DATA 148 | --database in your object explorer. For this tutorial, we are going to use a subset of objects from TPC-H set, representing 149 | --customer and their order. We are also going take some reference data about nations and regions. 150 | 151 | 152 | //Create two stages, one for each data class type - order and customer data. 153 | //Note: In production environment, these would likely be internal or external stages. 154 | --Alternatively, these feeds could be sourced via a Kafka connector. 155 | CREATE OR REPLACE STAGE CUSTOMER_DATA FILE_FORMAT = (TYPE = JSON); 156 | CREATE OR REPLACE STAGE ORDER_DATA FILE_FORMAT = (TYPE = CSV) ; 157 | 158 | //Generate and unload sample data. 159 | 160 | //Use object_construct as a quick way to create an object or document from all columns 161 | --and subsets of rows for the customer data and then offload it into CUSTOMER_DATA stage. 162 | 163 | //ORDER data would be extracted into compressed CSV files. 164 | 165 | //There are many additional options in COPY INTO stage construct but we are using INCLUDE_QUERY_ID 166 | --to make it easier to generate new incremental files as we are going to run these commands 167 | --over and over again, without a need to deal with file overloading. 168 | 169 | //Using relatively small number of records (i.e., LIMIT) as an example in this tutorial 170 | 171 | //Customer Data 172 | COPY INTO @CUSTOMER_DATA 173 | FROM 174 | (SELECT OBJECT_CONSTRUCT(*) 175 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.CUSTOMER LIMIT 20000) 176 | INCLUDE_QUERY_ID=TRUE; 177 | 178 | //Validate 179 | SELECT * FROM @CUSTOMER_DATA; 180 | 181 | //Validate 182 | SELECT METADATA$FILENAME,$1 FROM @CUSTOMER_DATA; 183 | 184 | //Validate 185 | LIST @CUSTOMER_DATA; 186 | 187 | //Order Data 188 | COPY INTO @ORDER_DATA 189 | FROM 190 | (SELECT * 191 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.ORDERS LIMIT 50000) 192 | INCLUDE_QUERY_ID=TRUE; 193 | 194 | //Validate 195 | //Expected error from the next SQL statement 196 | //SELECT * FROM @ORDER_DATA; 197 | 198 | //Validate 199 | SELECT METADATA$FILENAME,$1 FROM @ORDER_DATA; 200 | 201 | //Validate 202 | LIST @ORDER_DATA; 203 | 204 | 205 | //STAGING AREA SETUP - SAMPLE DATA 206 | 207 | //Setup Snowpipe to load data from files in a stage into staging tables. 208 | 209 | //Note: The REFRESH functionality is intended for short term use to resolve specific issues 210 | --when Snowpipe fails to load a subset of files and is not intended for regular use. 211 | 212 | //We're using the REFRESH in this tutorial to trigger Snowpipe explicitly to scan for new files. 213 | --In production environment, you'll likely enable AUTO_INGEST, connecting it with your 214 | --cloud storage events (like AWS SNS) and process new files automatically, 215 | 216 | //Create pipe for order 217 | CREATE OR REPLACE PIPE STG_ORDER_PP 218 | AS 219 | COPY INTO STG_ORDER 220 | FROM 221 | (SELECT $1,$2,$3,$4,$5,$6,$7,$8,$9, 222 | METADATA$FILENAME, METADATA$FILE_ROW_NUMBER, 223 | CURRENT_TIMESTAMP(), 'ORDER SYSTEM' 224 | FROM @ORDER_DATA); 225 | 226 | ALTER PIPE STG_ORDER_PP REFRESH; 227 | 228 | //Validate - no data 229 | SELECT * FROM STG_ORDER; 230 | SELECT METADATA$FILENAME,$1 FROM @ORDER_DATA; 231 | 232 | 233 | //Create pipe for customer 234 | CREATE OR REPLACE PIPE STG_CUSTOMER_PP 235 | AS 236 | COPY INTO STG_CUSTOMER 237 | FROM 238 | (SELECT $1, 239 | METADATA$FILENAME, METADATA$FILE_ROW_NUMBER, 240 | CURRENT_TIMESTAMP(), 'CUSTOMER SYSTEM' 241 | FROM @CUSTOMER_DATA); 242 | 243 | ALTER PIPE STG_CUSTOMER_PP REFRESH; 244 | 245 | 246 | //Validate - no data 247 | SELECT * FROM STG_CUSTOMER; 248 | SELECT METADATA$FILENAME,$1 FROM @CUSTOMER_DATA; 249 | 250 | //You should be able to see data appearing in the target tables and the stream on these tables. 251 | 252 | //As you would expect, the number of rows in a stream is exactly the same as in the base table. 253 | --This is because we didn't process or consume the delta of that stream yet. 254 | 255 | //Note: it may take a few seconds before the counts are reflected in the table 256 | 257 | USE SCHEMA L00_STG; 258 | 259 | SELECT 'STG_CUSTOMER', COUNT(1) FROM STG_CUSTOMER 260 | UNION ALL 261 | SELECT 'STG_ORDER', COUNT(1) FROM STG_ORDER 262 | UNION ALL 263 | SELECT 'STG_ORDER_STRM', COUNT(1) FROM STG_ORDER_STRM 264 | UNION ALL 265 | SELECT 'STG_CUSTOMER_STRM', COUNT(1) FROM STG_CUSTOMER_STRM; 266 | 267 | //We've established the basics and now, new data will be available via stream. 268 | 269 | //Next, we'll see if we can derive some of the business keys for the Data Vault entries in the model. 270 | 271 | //In our example, we will model it as a view on top of the stream that should allow us to perform 272 | --data parsing (raw_json -> columns) and business_key, hash_diff derivation on the fly. 273 | --Another thing to notice here is the use of SHA1_binary as hashing function. 274 | --There are many articles on choosing between MD5/SHA1(2)/other hash functions, so we won't focus on this. 275 | 276 | //For this tutorial, we are going to use fairly common SHA1 and its BINARY version from Snowflake arsenal 277 | --of functions that use less bytes to encode value than STRING. 278 | 279 | //Create Outbound view for Customer Stream 280 | CREATE OR REPLACE VIEW STG_CUSTOMER_STRM_OUTBOUND 281 | AS 282 | SELECT SRC.*, 283 | raw_json:C_CUSTKEY::NUMBER C_CUSTKEY, 284 | raw_json:C_NAME::STRING C_NAME, 285 | raw_json:C_ADDRESS::STRING C_ADDRESS, 286 | raw_json:C_NATIONKEY::NUMBER C_NATIONCODE, 287 | raw_json:C_PHONE::STRING C_PHONE, 288 | raw_json:C_ACCTBAL::NUMBER C_ACCTBAL, 289 | raw_json:C_MKTSEGMENT::STRING C_MKTSEGMENT, 290 | raw_json:C_COMMENT::STRING C_COMMENT, 291 | -------------------------------------------------------------------- 292 | -- derived business key 293 | -------------------------------------------------------------------- 294 | SHA1_BINARY(UPPER(TRIM(C_CUSTKEY))) SHA1_HUB_CUSTOMER, 295 | SHA1_BINARY(UPPER(ARRAY_TO_STRING 296 | (ARRAY_CONSTRUCT 297 | (NVL(TRIM(C_NAME) ,'-1'), 298 | NVL(TRIM(C_ADDRESS) ,'-1'), 299 | NVL(TRIM(C_NATIONCODE) ,'-1'), 300 | NVL(TRIM(C_PHONE) ,'-1'), 301 | NVL(TRIM(C_ACCTBAL) ,'-1'), 302 | NVL(TRIM(C_MKTSEGMENT) ,'-1'), 303 | NVL(TRIM(C_COMMENT) ,'-1')), 304 | '^'))) 305 | AS CUSTOMER_HASH_DIFF 306 | FROM STG_CUSTOMER_STRM SRC; 307 | 308 | 309 | //Query the view to validate the results. 310 | SELECT * FROM STG_CUSTOMER_STRM_OUTBOUND; 311 | 312 | 313 | //Create Outbound view for Order Stream 314 | CREATE OR REPLACE VIEW STG_ORDER_STRM_OUTBOUND 315 | AS 316 | SELECT SRC.*, 317 | -------------------------------------------------------------------- 318 | -- derived business key 319 | -------------------------------------------------------------------- 320 | SHA1_BINARY(UPPER(TRIM(O_ORDERKEY))) SHA1_HUB_ORDER, 321 | SHA1_BINARY(UPPER(TRIM(O_CUSTKEY))) SHA1_HUB_CUSTOMER, 322 | SHA1_BINARY(UPPER(ARRAY_TO_STRING(ARRAY_CONSTRUCT 323 | (NVL(TRIM(O_ORDERKEY) ,'-1'), 324 | NVL(TRIM(O_CUSTKEY) ,'-1')), 325 | '^'))) 326 | AS SHA1_LNK_CUSTOMER_ORDER, 327 | SHA1_BINARY(UPPER(ARRAY_TO_STRING(ARRAY_CONSTRUCT 328 | (NVL(TRIM(O_ORDERSTATUS) , '-1'), 329 | NVL(TRIM(O_TOTALPRICE) , '-1'), 330 | NVL(TRIM(O_ORDERDATE) , '-1'), 331 | NVL(TRIM(O_ORDERPRIORITY) , '-1'), 332 | NVL(TRIM(O_CLERK) , '-1'), 333 | NVL(TRIM(O_SHIPPRIORITY) , '-1'), 334 | NVL(TRIM(O_COMMENT) , '-1')), 335 | '^'))) 336 | AS ORDER_HASH_DIFF 337 | FROM STG_ORDER_STRM SRC; 338 | 339 | 340 | //Query the view to validate the results. 341 | SELECT * FROM STG_ORDER_STRM_OUTBOUND; 342 | 343 | //We've built out staging / inbound pipeline, ready to accommodate streaming data and 344 | --derived business keys that we are going to use in our Raw Data Vault 345 | 346 | 347 | //OPTIONAL -- VALIDATE 348 | 349 | USE SCHEMA L00_STG; 350 | SELECT * FROM STG_CUSTOMER; 351 | SELECT * FROM STG_NATION; 352 | SELECT * FROM STG_ORDER; 353 | SELECT * FROM STG_REGION; 354 | 355 | SELECT * FROM STG_CUSTOMER_STRM_OUTBOUND; 356 | SELECT * FROM STG_ORDER_STRM_OUTBOUND; 357 | 358 | SELECT * FROM @CUSTOMER_DATA; 359 | //SELECT * FROM @ORDER_DATA; 360 | 361 | SELECT * FROM STG_CUSTOMER_STRM; 362 | SELECT * FROM STG_ORDER_STRM; 363 | 364 | 365 | 366 | ----------------------------------------------------------------------------------- 367 | ----------------------------------------------------------------------------------- 368 | ----------------------------------------------------------------------------------- 369 | 370 | //BUILD RAW DATA VAULT - CUSTOMER AND ORDER HUBS 371 | 372 | //Deploy DDL for the HUBs, LINKs, and SATELLITE tables. 373 | USE SCHEMA L10_RDV; 374 | 375 | //Create Customer Hub 376 | CREATE OR REPLACE TABLE HUB_CUSTOMER 377 | (SHA1_HUB_CUSTOMER BINARY NOT NULL, 378 | C_CUSTKEY NUMBER NOT NULL, 379 | LDTS TIMESTAMP NOT NULL, 380 | RSCR STRING NOT NULL, 381 | CONSTRAINT PK_HUB_CUSTOMER PRIMARY KEY(SHA1_HUB_CUSTOMER)); 382 | 383 | 384 | //Create Order Hub 385 | CREATE OR REPLACE TABLE HUB_ORDER 386 | (SHA1_HUB_ORDER BINARY NOT NULL, 387 | O_ORDERKEY NUMBER NOT NULL, 388 | LDTS TIMESTAMP NOT NULL, 389 | RSCR STRING NOT NULL, 390 | CONSTRAINT PK_HUB_ORDER PRIMARY KEY(SHA1_HUB_ORDER)); 391 | 392 | 393 | //BUILD RAW DATA VAULT - CUSTOMER AND ORDER SATELLITES 394 | 395 | //Create Customer Satellite 396 | CREATE OR REPLACE TABLE SAT_CUSTOMER 397 | (SHA1_HUB_CUSTOMER BINARY NOT NULL, 398 | LDTS TIMESTAMP NOT NULL, 399 | C_NAME STRING, 400 | C_ADDRESS STRING, 401 | C_PHONE STRING, 402 | C_ACCTBAL NUMBER, 403 | C_MKTSEGMENT STRING, 404 | C_COMMENT STRING, 405 | NATIONCODE NUMBER, 406 | HASH_DIFF BINARY NOT NULL, 407 | RSCR STRING NOT NULL, 408 | CONSTRAINT PK_SAT_CUSTOMER PRIMARY KEY(SHA1_HUB_CUSTOMER, LDTS), 409 | CONSTRAINT FK_SAT_CUSTOMER FOREIGN KEY(SHA1_HUB_CUSTOMER) REFERENCES HUB_CUSTOMER); 410 | 411 | 412 | //Create ORDER Satellite 413 | CREATE OR REPLACE TABLE SAT_ORDER 414 | (SHA1_HUB_ORDER BINARY NOT NULL, 415 | LDTS TIMESTAMP NOT NULL, 416 | O_ORDERSTATUS STRING, 417 | O_TOTALPRICE NUMBER, 418 | O_ORDERDATE DATE, 419 | O_ORDERPRIORITY STRING, 420 | O_CLERK STRING, 421 | O_SHIPPRIORITY NUMBER, 422 | O_COMMENT STRING, 423 | HASH_DIFF BINARY NOT NULL, 424 | RSCR STRING NOT NULL, 425 | CONSTRAINT PK_SAT_ORDER PRIMARY KEY(SHA1_HUB_ORDER, LDTS), 426 | CONSTRAINT FK_SAT_ORDER FOREIGN KEY(SHA1_HUB_ORDER) REFERENCES HUB_ORDER); 427 | 428 | 429 | //BUILD RAW DATA VAULT - CUSTOMER_ORDER Link 430 | 431 | //Create the CUSTOMER_ORDER Link 432 | CREATE OR REPLACE TABLE LNK_CUSTOMER_ORDER 433 | (SHA1_LNK_CUSTOMER_ORDER BINARY NOT NULL, 434 | SHA1_HUB_CUSTOMER BINARY, 435 | SHA1_HUB_ORDER BINARY, 436 | LDTS TIMESTAMP NOT NULL, 437 | RSCR STRING NOT NULL, 438 | CONSTRAINT PK_LNK_CUSTOMER_ORDER PRIMARY KEY(SHA1_LNK_CUSTOMER_ORDER), 439 | CONSTRAINT FK1_LNK_CUSTOMER_ORDER FOREIGN KEY(SHA1_HUB_CUSTOMER) REFERENCES HUB_CUSTOMER, 440 | CONSTRAINT FK2_LNK_CUSTOMER_ORDER FOREIGN KEY(SHA1_HUB_ORDER) REFERENCES HUB_ORDER); 441 | 442 | //BUILD RAW DATA VAULT - REFERENCE TABLES 443 | 444 | //Create Region Reference 445 | CREATE OR REPLACE TABLE REF_REGION 446 | (REGIONCODE NUMBER, 447 | LDTS TIMESTAMP, 448 | RSCR STRING NOT NULL, 449 | R_NAME STRING, 450 | R_COMMENT STRING, 451 | CONSTRAINT PK_REF_REGION PRIMARY KEY (REGIONCODE)) 452 | AS 453 | SELECT R_REGIONKEY, LDTS, RSCR, R_NAME, R_COMMENT 454 | FROM L00_STG.STG_REGION; 455 | 456 | //Validate 457 | SELECT * FROM REF_REGION; 458 | 459 | 460 | //Create Nation Reference 461 | CREATE OR REPLACE TABLE REF_NATION 462 | (NATIONCODE NUMBER, 463 | REGIONCODE NUMBER, 464 | LDTS TIMESTAMP, 465 | RSCR STRING NOT NULL, 466 | N_NAME STRING, 467 | N_COMMENT STRING, 468 | CONSTRAINT PK_REF_NATION PRIMARY KEY (NATIONCODE), 469 | CONSTRAINT FK_REF_REGION FOREIGN KEY (REGIONCODE) REFERENCES REF_REGION(REGIONCODE)) 470 | AS 471 | SELECT N_NATIONKEY, N_REGIONKEY, LDTS, RSCR, N_NAME, N_COMMENT 472 | FROM L00_STG.STG_NATION; 473 | 474 | //Validate 475 | SELECT * FROM REF_NATION; 476 | 477 | 478 | 479 | //BUILD RAW DATA VAULT - CREATE TASKS 480 | 481 | 482 | //Now we have source data waiting in our staging streams and views and we have target Raw Data Vaults tables. 483 | --We now need to connect the dots. We are going to create tasks, one per each stream so whenever 484 | --there is new records coming in a stream, that delta will be incrementally propagated to all 485 | --dependent RDV models in one go. 486 | 487 | //To achieve that, we are going to use multi-table insert functionality 488 | --As you can see, tasks can be set up to run on a 489 | --pre-defined frequency (every 1 minute in our example) and use dedicated virtual warehouse 490 | --as a compute power (in our tutorial we are going to use same warehouse for all tasks, 491 | --though this could be as granular as needed). 492 | --Also, before waking up compute resource, tasks are going to check that there is data 493 | --in a corresponding stream to process. 494 | 495 | //Create Task for Customer Stream 496 | CREATE OR REPLACE TASK CUSTOMER_STRM_TSK 497 | WAREHOUSE = DV_RDV_WH 498 | SCHEDULE = '1 minute' 499 | WHEN 500 | SYSTEM$STREAM_HAS_DATA('L00_STG.STG_CUSTOMER_STRM') 501 | AS INSERT ALL 502 | WHEN (SELECT COUNT(1) FROM HUB_CUSTOMER TGT WHERE TGT.SHA1_HUB_CUSTOMER = SRC_SHA1_HUB_CUSTOMER) = 0 503 | THEN INTO HUB_CUSTOMER 504 | (SHA1_HUB_CUSTOMER, C_CUSTKEY, LDTS, RSCR) 505 | VALUES (SRC_SHA1_HUB_CUSTOMER, SRC_C_CUSTKEY, SRC_LDTS, SRC_RSCR) 506 | WHEN (SELECT COUNT(1) FROM SAT_CUSTOMER TGT WHERE TGT.SHA1_HUB_CUSTOMER = SRC_SHA1_HUB_CUSTOMER AND 507 | TGT.HASH_DIFF = SRC_CUSTOMER_HASH_DIFF) = 0 508 | THEN INTO SAT_CUSTOMER 509 | (SHA1_HUB_CUSTOMER, LDTS, C_NAME, C_ADDRESS, C_PHONE, C_ACCTBAL, C_MKTSEGMENT, C_COMMENT, 510 | NATIONCODE, HASH_DIFF, RSCR) 511 | VALUES (SRC_SHA1_HUB_CUSTOMER, SRC_LDTS, SRC_C_NAME, SRC_C_ADDRESS, SRC_C_PHONE, SRC_C_ACCTBAL, 512 | SRC_C_MKTSEGMENT, SRC_C_COMMENT, SRC_NATIONCODE, SRC_CUSTOMER_HASH_DIFF, SRC_RSCR) 513 | SELECT 514 | SHA1_HUB_CUSTOMER SRC_SHA1_HUB_CUSTOMER, 515 | C_CUSTKEY SRC_C_CUSTKEY, 516 | C_NAME SRC_C_NAME, 517 | C_ADDRESS SRC_C_ADDRESS, 518 | C_NATIONCODE SRC_NATIONCODE, 519 | C_PHONE SRC_C_PHONE, 520 | C_ACCTBAL SRC_C_ACCTBAL, 521 | C_MKTSEGMENT SRC_C_MKTSEGMENT, 522 | C_COMMENT SRC_C_COMMENT, 523 | CUSTOMER_HASH_DIFF SRC_CUSTOMER_HASH_DIFF, 524 | LDTS SRC_LDTS, 525 | RSCR SRC_RSCR 526 | FROM L00_STG.STG_CUSTOMER_STRM_OUTBOUND SRC; 527 | 528 | ALTER TASK CUSTOMER_STRM_TSK RESUME; 529 | 530 | 531 | 532 | //Create task for ORDER Stream 533 | CREATE OR REPLACE TASK ORDER_STRM_TSK 534 | WAREHOUSE = DV_RDV_WH 535 | SCHEDULE = '1 minute' 536 | WHEN 537 | SYSTEM$STREAM_HAS_DATA('L00_STG.STG_ORDER_STRM') 538 | AS INSERT ALL 539 | WHEN (SELECT COUNT(1) FROM HUB_ORDER TGT WHERE TGT.SHA1_HUB_ORDER = SRC_SHA1_HUB_ORDER) = 0 540 | THEN INTO HUB_ORDER 541 | (SHA1_HUB_ORDER, O_ORDERKEY, LDTS, RSCR) 542 | VALUES (SRC_SHA1_HUB_ORDER, SRC_O_ORDERKEY, SRC_LDTS, SRC_RSCR) 543 | WHEN (SELECT COUNT(1) FROM SAT_ORDER TGT WHERE TGT.SHA1_HUB_ORDER = SRC_SHA1_HUB_ORDER AND TGT.HASH_DIFF = SRC_ORDER_HASH_DIFF) = 0 544 | THEN INTO SAT_ORDER 545 | (SHA1_HUB_ORDER, LDTS, O_ORDERSTATUS, O_TOTALPRICE, O_ORDERDATE, O_ORDERPRIORITY, O_CLERK, 546 | O_SHIPPRIORITY, O_COMMENT, HASH_DIFF, RSCR) 547 | VALUES (SRC_SHA1_HUB_ORDER, SRC_LDTS, SRC_O_ORDERSTATUS, SRC_O_TOTALPRICE, SRC_O_ORDERDATE, 548 | SRC_O_ORDERPRIORITY, SRC_O_CLERK, SRC_O_SHIPPRIORITY, SRC_O_COMMENT, SRC_ORDER_HASH_DIFF, SRC_RSCR) 549 | WHEN (SELECT COUNT(1) FROM LNK_CUSTOMER_ORDER TGT 550 | WHERE TGT.SHA1_LNK_CUSTOMER_ORDER = SRC_SHA1_LNK_CUSTOMER_ORDER) = 0 551 | THEN INTO LNK_CUSTOMER_ORDER 552 | (SHA1_LNK_CUSTOMER_ORDER, SHA1_HUB_CUSTOMER, SHA1_HUB_ORDER, LDTS, RSCR) 553 | VALUES (SRC_SHA1_LNK_CUSTOMER_ORDER, SRC_SHA1_HUB_CUSTOMER, SRC_SHA1_HUB_ORDER, SRC_LDTS, SRC_RSCR) 554 | SELECT 555 | SHA1_HUB_ORDER SRC_SHA1_HUB_ORDER, 556 | SHA1_LNK_CUSTOMER_ORDER SRC_SHA1_LNK_CUSTOMER_ORDER, 557 | SHA1_HUB_CUSTOMER SRC_SHA1_HUB_CUSTOMER, 558 | O_ORDERKEY SRC_O_ORDERKEY, 559 | O_ORDERSTATUS SRC_O_ORDERSTATUS, 560 | O_TOTALPRICE SRC_O_TOTALPRICE, 561 | O_ORDERDATE SRC_O_ORDERDATE, 562 | O_ORDERPRIORITY SRC_O_ORDERPRIORITY, 563 | O_CLERK SRC_O_CLERK, 564 | O_SHIPPRIORITY SRC_O_SHIPPRIORITY, 565 | O_COMMENT SRC_O_COMMENT, 566 | ORDER_HASH_DIFF SRC_ORDER_HASH_DIFF, 567 | LDTS SRC_LDTS, 568 | RSCR SRC_RSCR 569 | FROM L00_STG.STG_ORDER_STRM_OUTBOUND SRC; 570 | 571 | ALTER TASK ORDER_STRM_TSK RESUME; 572 | 573 | 574 | 575 | 576 | //Once tasks are created and resumed (by default, they are initially suspended), 577 | //let's have a look on the task execution history to see how the process will start. 578 | SELECT * 579 | FROM TABLE(INFORMATION_SCHEMA.TASK_HISTORY()) 580 | ORDER BY SCHEDULED_TIME DESC; 581 | 582 | //Notice how after successful execution, next two tasks run were automatically SKIPPED as there were nothing in the stream and there is nothing to do. 583 | 584 | //We can also check content and stats of the objects involved. 585 | --Please notice that views on streams in our staging area are no longer returning any rows. 586 | --This is because that delta of changes was consumed by a successfully completed DML transaction (in our case, embedded in tasks). 587 | --This way you don't need to spend any time implementing incremental detection / processing logic on the application side. 588 | SELECT 'HUB_CUSTOMER', COUNT(1) FROM HUB_CUSTOMER 589 | UNION ALL 590 | SELECT 'HUB_ORDER', COUNT(1) FROM HUB_ORDER 591 | UNION ALL 592 | SELECT 'SAT_CUSTOMER', COUNT(1) FROM SAT_CUSTOMER 593 | UNION ALL 594 | SELECT 'SAT_ORDER', COUNT(1) FROM SAT_ORDER 595 | UNION ALL 596 | SELECT 'LNK_CUSTOMER_ORDER', COUNT(1) FROM LNK_CUSTOMER_ORDER 597 | UNION ALL 598 | SELECT 'L00_STG.STG_CUSTOMER_STRM_OUTBOUND', COUNT(1) FROM L00_STG.STG_CUSTOMER_STRM_OUTBOUND 599 | UNION ALL 600 | SELECT 'L00_STG.STG_ORDER_STRM_OUTBOUND', COUNT(1) FROM L00_STG.STG_ORDER_STRM_OUTBOUND; 601 | 602 | //We now have data in our Raw Data Vault core structures. Let's move on and talk about the concept of virtualization for building your near-real time Data Vault solution. 603 | 604 | ----------------------------------------------------------------------------------- 605 | ----------------------------------------------------------------------------------- 606 | ----------------------------------------------------------------------------------- 607 | 608 | //VIEWS FOR AGILE REPORTING 609 | //One of the great benefits of having the compute power from Snowflake is that now it is totally possible to have most of your business vault and information marts in a Data Vault architecture be built exclusively from views. There is no longer a need to have the argument that there are "too many joins" or that the response won't be fast enough. The elasticity of the Snowflake virtual warehouses combined with our dynamic optimization engine have solved that problem. (For more details, see this post) 610 | 611 | //If you really want to deliver data to the business users and data scientists in NRT, in our opinion using views is the only option. Once you have the streaming loads built to feed your Data Vault, the fastest way to make that data visible downstream will be views. Using views allows you to deliver the data faster by eliminating any latency that would be incurred by having additional ELT processes between the Data Vault and the data consumers downstream. 612 | //All the business logic, alignment, and formatting of the data can be in the view code. That means fewer moving parts to debug, and reduces the storage needed as well. 613 | 614 | //Looking at the diagram above you will see an example of how virtualization could fit in the architecture. Here, solid lines are representing physical tables and dotted lines - views. You incrementally ingest data into Raw Data Vault and all downstream transformations are applied as views. From a data consumer perspective when working with a virtualized information mart, the query always shows everything known by your data vault, right up to the point the query was submitted. 615 | //With Snowflake you have the ability to provide as much compute as required, on-demand, without a risk of causing performance impact on any surrounding processes and pay only for what you use. This makes materialization of transformations in layers like Business Data Vault and Information delivery an option rather than a must-have. Instead of "optimizing upfront" you can now make this decision based on the usage pattern characteristics, such as frequency of use, type of queries, latency requirements, readiness of the requirements etc. 616 | 617 | //Many modern data engineering automation frameworks are already actively supporting virtualization of logic. Several tools offer a low-code or configuration-like ability to switch between materializing an object as a view or a physical table, automatically generating all required DDL & DML. This could be applied on specific objects, layers or/and be environment specific. So even if you start with a view, you can easily refactor to use a table if user requirements evolve. 618 | //As said before, virtualization is not only a way to improve time-to-value and provide near real time access to the data, given the scalability and workload isolation of Snowflake, virtualization also is a design technique that could make your Data Vault excel: minimizing cost-of-change, accelerating the time-to-delivery and becoming an extremely agile, future proof solution for ever growing business needs. 619 | 620 | 621 | ----------------------------------------------------------------------------------- 622 | ----------------------------------------------------------------------------------- 623 | ----------------------------------------------------------------------------------- 624 | 625 | 626 | //BUILD: Business Data Vault 627 | //As a quick example of using views for transformations we just discussed, here is how enrichment of 628 | --customer descriptive data could happen in Business Data Vault, connecting data received from 629 | --source with some reference data. 630 | 631 | //Let's create a view that will perform these additional derivations on the fly. 632 | //Assuming non-functional capabilities are satisfying our requirements, 633 | --deploying (and re-deploying a new version) transformations in this way is super easy. 634 | USE SCHEMA L20_BDV; 635 | CREATE OR REPLACE VIEW SAT_CUSTOMER_BV 636 | AS 637 | SELECT RSC.SHA1_HUB_CUSTOMER, RSC.LDTS, RSC.C_NAME, RSC.C_ADDRESS, RSC.C_PHONE, 638 | RSC.C_ACCTBAL, RSC.C_MKTSEGMENT, RSC.C_COMMENT, RSC.NATIONCODE, RSC.RSCR, 639 | -- derived 640 | RRN.N_NAME NATION_NAME, 641 | RRR.R_NAME REGION_NAME 642 | FROM L10_RDV.SAT_CUSTOMER RSC 643 | LEFT OUTER JOIN L10_RDV.REF_NATION RRN 644 | ON (RSC.NATIONCODE = RRN.NATIONCODE) 645 | LEFT OUTER JOIN L10_RDV.REF_REGION RRR 646 | ON (RRN.REGIONCODE = RRR.REGIONCODE); 647 | 648 | //Verify 649 | SELECT * FROM SAT_CUSTOMER_BV; 650 | 651 | //Now let's imagine we have a heavier transformation to perform that it would make more sense 652 | --to materialize it as a table. It could be more data volume, could be more complex logic, 653 | --PITs, bridges or even an object that will be used frequently and by many users. 654 | --For this case, let's first build a new business satellite that for illustration purposes 655 | --will be deriving additional classification / tiering for orders based on the conditional logic. 656 | CREATE OR REPLACE TABLE SAT_ORDER_BV 657 | (SHA1_HUB_ORDER BINARY NOT NULL, 658 | LDTS TIMESTAMP NOT NULL, 659 | O_ORDERSTATUS STRING, 660 | O_TOTALPRICE NUMBER, 661 | O_ORDERDATE DATE, 662 | O_ORDERPRIORITY STRING, 663 | O_CLERK STRING, 664 | O_SHIPPRIORITY NUMBER, 665 | O_COMMENT STRING, 666 | HASH_DIFF BINARY NOT NULL, 667 | RSCR STRING NOT NULL, 668 | -- additional attributes 669 | ORDER_PRIORITY_BUCKET STRING, 670 | CONSTRAINT PK_SAT_ORDER PRIMARY KEY(SHA1_HUB_ORDER, LDTS), 671 | CONSTRAINT FK_SAT_ORDER FOREIGN KEY(SHA1_HUB_ORDER) REFERENCES L10_RDV.HUB_ORDER) 672 | AS 673 | SELECT SHA1_HUB_ORDER, LDTS, O_ORDERSTATUS, O_TOTALPRICE, O_ORDERDATE, O_ORDERPRIORITY, 674 | O_CLERK, O_SHIPPRIORITY, O_COMMENT, HASH_DIFF, RSCR, 675 | -- derived additional attributes 676 | CASE WHEN O_ORDERPRIORITY IN ('2-HIGH', '1-URGENT') AND O_TOTALPRICE >= 200000 THEN 'Tier-1' 677 | WHEN O_ORDERPRIORITY IN ('3-MEDIUM', '2-HIGH', '1-URGENT') AND O_TOTALPRICE BETWEEN 150000 AND 200000 THEN 'Tier-2' 678 | ELSE 'Tier-3' 679 | END ORDER_PRIORITY_BUCKET 680 | FROM L10_RDV.SAT_ORDER; 681 | 682 | 683 | //VALIDATE 684 | SELECT * FROM SAT_ORDER_BV; 685 | 686 | //What we are going to do from processing/orchestration perspective is extending our 687 | --ORDER processing pipeline so that when the task populates a l10_rdv.sat_ORDER this 688 | --will generate a new stream of changes and these changes are going to be propagated 689 | --by a dependent task to l20_bdv.sat_ORDER_bv. This is super easy to do as tasks in 690 | --Snowflake can be not only schedule-based but also start automatically once the 691 | --parent task is completed. 692 | CREATE OR REPLACE STREAM L10_RDV.SAT_ORDER_STRM ON TABLE L10_RDV.SAT_ORDER; 693 | 694 | 695 | ALTER TASK L10_RDV.ORDER_STRM_TSK SUSPEND; 696 | 697 | 698 | CREATE OR REPLACE TASK L10_RDV.HUB_ORDER_STRM_SAT_ORDER_BV_TSK 699 | WAREHOUSE = DV_RDV_WH 700 | AFTER L10_RDV.ORDER_STRM_TSK 701 | AS 702 | INSERT INTO L20_BDV.SAT_ORDER_BV 703 | SELECT 704 | SHA1_HUB_ORDER, LDTS, O_ORDERSTATUS, O_TOTALPRICE, O_ORDERDATE, O_ORDERPRIORITY, 705 | O_CLERK, O_SHIPPRIORITY, O_COMMENT, HASH_DIFF, RSCR, 706 | -- derived additional attributes 707 | CASE 708 | WHEN O_ORDERPRIORITY IN ('2-HIGH', '1-URGENT') AND O_TOTALPRICE >= 200000 THEN 'Tier-1' 709 | WHEN O_ORDERPRIORITY IN ('3-MEDIUM', '2-HIGH', '1-URGENT') AND O_TOTALPRICE BETWEEN 150000 AND 200000 THEN 'Tier-2' 710 | ELSE 'Tier-3' 711 | END ORDER_PRIORITY_BUCKET 712 | FROM SAT_ORDER_STRM; 713 | 714 | ALTER TASK L10_RDV.HUB_ORDER_STRM_SAT_ORDER_BV_TSK RESUME; 715 | ALTER TASK L10_RDV.ORDER_STRM_TSK RESUME; 716 | 717 | 718 | //Now let's go back to our staging area to process another slice of data to test the task 719 | USE SCHEMA L00_STG; 720 | COPY INTO @ORDER_DATA 721 | FROM 722 | (SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.ORDERS LIMIT 125000) 723 | --Removed the limit 724 | INCLUDE_QUERY_ID=TRUE; 725 | 726 | ALTER PIPE STG_ORDER_PP REFRESH; 727 | 728 | 729 | 730 | //Data is not automatically flowing through all the layers via asynchronous tasks. 731 | --With the results, you can validate: 732 | SELECT 'L00_STG.STG_ORDER', COUNT(1) FROM L00_STG.STG_ORDER 733 | UNION ALL 734 | SELECT 'L00_STG.STG_ORDER_STRM', COUNT(1) FROM L00_STG.STG_ORDER_STRM 735 | UNION ALL 736 | SELECT 'L10_RDV.SAT_ORDER', COUNT(1) FROM L10_RDV.SAT_ORDER 737 | UNION ALL 738 | SELECT 'L10_RDV.SAT_ORDER_STRM', COUNT(1) FROM L10_RDV.SAT_ORDER_STRM 739 | UNION ALL 740 | SELECT 'L20_BDV.SAT_ORDER_BV', COUNT(1) FROM L20_BDV.SAT_ORDER_BV; 741 | 742 | 743 | SELECT * 744 | FROM TABLE(INFORMATION_SCHEMA.TASK_HISTORY()) 745 | ORDER BY SCHEDULED_TIME DESC; 746 | 747 | 748 | 749 | //Now let's go back to our staging area to process another slice of data to test the task 750 | USE SCHEMA L00_STG; 751 | COPY INTO @ORDER_DATA 752 | FROM 753 | (SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.ORDERS) 754 | --Removed the limit 755 | INCLUDE_QUERY_ID=TRUE; 756 | 757 | ALTER PIPE STG_ORDER_PP REFRESH; 758 | 759 | 760 | 761 | //Data is not automatically flowing through all the layers via asynchronous tasks. 762 | --With the results, you can validate: 763 | SELECT 'L00_STG.STG_ORDER', COUNT(1) FROM L00_STG.STG_ORDER 764 | UNION ALL 765 | SELECT 'L00_STG.STG_ORDER_STRM', COUNT(1) FROM L00_STG.STG_ORDER_STRM 766 | UNION ALL 767 | SELECT 'L10_RDV.SAT_ORDER', COUNT(1) FROM L10_RDV.SAT_ORDER 768 | UNION ALL 769 | SELECT 'L10_RDV.SAT_ORDER_STRM', COUNT(1) FROM L10_RDV.SAT_ORDER_STRM 770 | UNION ALL 771 | SELECT 'L20_BDV.SAT_ORDER_BV', COUNT(1) FROM L20_BDV.SAT_ORDER_BV; 772 | 773 | 774 | SELECT * 775 | FROM TABLE(INFORMATION_SCHEMA.TASK_HISTORY()) 776 | ORDER BY SCHEDULED_TIME DESC; 777 | 778 | 779 | 780 | //Now let's go back to our staging area to process another slice of data to test the task 781 | USE SCHEMA L00_STG; 782 | COPY INTO @ORDER_DATA 783 | FROM 784 | (SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.ORDERS LIMIT 33333) 785 | INCLUDE_QUERY_ID=TRUE; 786 | 787 | ALTER PIPE STG_ORDER_PP REFRESH; 788 | 789 | 790 | 791 | //Data is not automatically flowing through all the layers via asynchronous tasks. 792 | --With the results, you can validate: 793 | SELECT 'L00_STG.STG_ORDER', COUNT(1) FROM L00_STG.STG_ORDER 794 | UNION ALL 795 | SELECT 'L00_STG.STG_ORDER_STRM', COUNT(1) FROM L00_STG.STG_ORDER_STRM 796 | UNION ALL 797 | SELECT 'L10_RDV.SAT_ORDER', COUNT(1) FROM L10_RDV.SAT_ORDER 798 | UNION ALL 799 | SELECT 'L10_RDV.SAT_ORDER_STRM', COUNT(1) FROM L10_RDV.SAT_ORDER_STRM 800 | UNION ALL 801 | SELECT 'L20_BDV.SAT_ORDER_BV', COUNT(1) FROM L20_BDV.SAT_ORDER_BV; 802 | 803 | 804 | SELECT * 805 | FROM TABLE(INFORMATION_SCHEMA.TASK_HISTORY()) 806 | ORDER BY SCHEDULED_TIME DESC; 807 | 808 | 809 | 810 | 811 | 812 | //Now let's go back to our staging area to process another slice of data to test the task 813 | USE SCHEMA L00_STG; 814 | COPY INTO @ORDER_DATA 815 | FROM 816 | (SELECT * FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.ORDERS) 817 | --Removed the limit 818 | INCLUDE_QUERY_ID=TRUE; 819 | 820 | ALTER PIPE STG_ORDER_PP REFRESH; 821 | 822 | 823 | 824 | //Data is not automatically flowing through all the layers via asynchronous tasks. 825 | --With the results, you can validate: 826 | SELECT 'L00_STG.STG_ORDER', COUNT(1) FROM L00_STG.STG_ORDER 827 | UNION ALL 828 | SELECT 'L00_STG.STG_ORDER_STRM', COUNT(1) FROM L00_STG.STG_ORDER_STRM 829 | UNION ALL 830 | SELECT 'L10_RDV.SAT_ORDER', COUNT(1) FROM L10_RDV.SAT_ORDER 831 | UNION ALL 832 | SELECT 'L10_RDV.SAT_ORDER_STRM', COUNT(1) FROM L10_RDV.SAT_ORDER_STRM 833 | UNION ALL 834 | SELECT 'L20_BDV.SAT_ORDER_BV', COUNT(1) FROM L20_BDV.SAT_ORDER_BV; 835 | 836 | 837 | SELECT * 838 | FROM TABLE(INFORMATION_SCHEMA.TASK_HISTORY()) 839 | ORDER BY SCHEDULED_TIME DESC; 840 | 841 | 842 | 843 | 844 | ----------------------------------------------------------------------------------- 845 | ----------------------------------------------------------------------------------- 846 | ----------------------------------------------------------------------------------- 847 | 848 | 849 | //BUILD: Information Delivery 850 | //When it comes to the Information Delivery layer we are not changing the meaning of data, 851 | --but we may change format to simplify users to access and work with the 852 | --data products/output interfaces. Different consumers may have different needs and preferences, 853 | --some would prefer star/snowflake dimensional schemas, some would adhere to use 854 | --flattened objects or even transform data into JSON/parquet objects. 855 | 856 | //First things we would like to add to simplify working with satellites 857 | --is creating views that shows latest version for each key. 858 | -------------------------------------------------------------------- 859 | -- RDV curr views 860 | -------------------------------------------------------------------- 861 | USE SCHEMA L10_RDV; 862 | 863 | CREATE OR REPLACE VIEW SAT_CUSTOMER_CURR_VW 864 | AS 865 | SELECT * FROM SAT_CUSTOMER 866 | QUALIFY LEAD(LDTS) OVER (PARTITION BY SHA1_HUB_CUSTOMER ORDER BY LDTS) IS NULL; 867 | 868 | 869 | CREATE OR REPLACE VIEW SAT_ORDER_CURR_VW 870 | AS 871 | SELECT * FROM SAT_ORDER 872 | QUALIFY LEAD(LDTS) OVER (PARTITION BY SHA1_HUB_ORDER ORDER BY LDTS) IS NULL; 873 | -------------------------------------------------------------------- 874 | -- BDV curr views 875 | -------------------------------------------------------------------- 876 | USE SCHEMA L20_BDV; 877 | 878 | CREATE OR REPLACE VIEW SAT_ORDER_BV_CURR_VW 879 | AS 880 | SELECT * FROM SAT_ORDER_BV 881 | QUALIFY LEAD(LDTS) OVER (PARTITION BY SHA1_HUB_ORDER ORDER BY LDTS) IS NULL; 882 | 883 | 884 | CREATE VIEW SAT_CUSTOMER_BV_CURR_VW 885 | AS 886 | SELECT * FROM SAT_CUSTOMER_BV 887 | QUALIFY LEAD(LDTS) OVER (PARTITION BY SHA1_HUB_CUSTOMER ORDER BY LDTS) IS NULL; 888 | 889 | 890 | 891 | //Let's create a simple dimensional structure. Again, we will keep it virtual(as views) to start with, 892 | --but you already know that depending on access characteristics required any of these 893 | --could be selectively materialized. 894 | USE SCHEMA L30_INFO; 895 | 896 | -- DIM TYPE 1 897 | CREATE OR REPLACE VIEW DIM1_CUSTOMER 898 | AS 899 | SELECT 900 | HUB.SHA1_HUB_CUSTOMER AS DIM_CUSTOMER_KEY, 901 | SAT.LDTS AS EFFECTIVE_DTS, 902 | HUB.C_CUSTKEY AS CUSTOMER_ID, 903 | SAT.RSCR AS RECORD_SOURCE, 904 | SAT.* 905 | FROM 906 | L10_RDV.HUB_CUSTOMER HUB, 907 | L20_BDV.SAT_CUSTOMER_BV_CURR_VW SAT 908 | WHERE HUB.SHA1_HUB_CUSTOMER = SAT.SHA1_HUB_CUSTOMER; 909 | 910 | -- DIM TYPE 1 911 | CREATE OR REPLACE VIEW DIM1_ORDER 912 | AS 913 | SELECT 914 | 915 | HUB.SHA1_HUB_ORDER AS DIM_ORDER_KEY, 916 | SAT.LDTS AS EFFECTIVE_DTS, 917 | HUB.O_ORDERKEY AS ORDER_ID, 918 | SAT.RSCR AS RECORD_SOURCE, 919 | SAT.* 920 | FROM 921 | L10_RDV.HUB_ORDER HUB, 922 | L20_BDV.SAT_ORDER_BV_CURR_VW SAT 923 | WHERE HUB.SHA1_HUB_ORDER = SAT.SHA1_HUB_ORDER; 924 | 925 | -- FACT table 926 | CREATE OR REPLACE VIEW FCT_CUSTOMER_ORDER 927 | AS 928 | SELECT 929 | LNK.LDTS AS EFFECTIVE_DTS, 930 | LNK.RSCR AS RECORD_SOURCE, 931 | LNK.SHA1_HUB_CUSTOMER AS DIM_CUSTOMER_KEY, 932 | LNK.SHA1_HUB_ORDER AS DIM_ORDER_KEY 933 | -- this is a factless fact, but here you can add any measures, calculated or derived 934 | FROM L10_RDV.LNK_CUSTOMER_ORDER LNK; 935 | 936 | 937 | 938 | //All good so far? 939 | //Now lets try to query fct_customer_order. You may find that the view does not return any rows. Why? 940 | --If you remember, when we were unloading sample data, we took a subset of random orders and a subset of random customers. 941 | --Thus, it is possible that there won't be any overlap, Therefore doing the inner join with dim1_order will likely result 942 | --in all rows being eliminated from the resultset. Thankfully we are using Data Vault and all we need to do is go and load 943 | --the full customer dataset. Just think about it, there is no need to reprocess any links or fact tables simply because 944 | --customer/reference feed was incomplete. Lets go and see if we can resolve this. 945 | USE SCHEMA L00_STG; 946 | COPY INTO @CUSTOMER_DATA 947 | FROM 948 | (SELECT OBJECT_CONSTRUCT(*) 949 | FROM SNOWFLAKE_SAMPLE_DATA.TPCH_SF10.CUSTOMER) 950 | -- removed LIMIT 951 | INCLUDE_QUERY_ID=TRUE; 952 | 953 | ALTER PIPE STG_CUSTOMER_PP REFRESH; 954 | 955 | //All you need to do now is just wait a few seconds whilst our continuous data pipeline will automatically propagate 956 | --new customer data into Raw Data Vault. Quick check for the records count in customer dimension now shows 957 | --that there are 1.5Mn records: 958 | USE SCHEMA L30_INFO; 959 | SELECT COUNT(1) FROM DIM1_CUSTOMER; 960 | //Note that if the result is zero, wait a few seconds and rerun the query 961 | 962 | 963 | //Finally lets wear user's hat and run a query to break down ORDER by nation, region and ORDER_PRIORITY_BUCKET which 964 | -- are all attributes we derived in Business Data Vault. As we are using Snowsight, why not quickly creating a chart 965 | --from this result set to better understand the data. For this simply click on the ‘Chart' section on the bottom pane 966 | --and put attributes/measures as it is shown on the screenshot below. 967 | SELECT DC.NATION_NAME, DC.REGION_NAME, DO.ORDER_PRIORITY_BUCKET, COUNT(1) CNT_ORDER 968 | FROM FCT_CUSTOMER_ORDER FCT, 969 | DIM1_CUSTOMER DC, 970 | DIM1_ORDER DO 971 | WHERE FCT.DIM_CUSTOMER_KEY = DC.DIM_CUSTOMER_KEY AND 972 | FCT.DIM_ORDER_KEY = DO.DIM_ORDER_KEY 973 | GROUP BY 1,2,3; 974 | 975 | SELECT * FROM FCT_CUSTOMER_ORDER; 976 | SELECT * FROM DIM1_CUSTOMER; 977 | SELECT * FROM DIM1_ORDER; 978 | 979 | //Simplicity of engineering, openness, scalable performance, enterprise-grade governance enabled by the core of the Snowflake platform are now allowing teams to focus on what matters most for the business and build truly agile, collaborative data environments. Teams can now connect data from all parts of the landscape, until there are no stones left unturned. They are even tapping into new datasets via live access to the Snowflake Data Marketplace. The Snowflake Data Cloud combined with a Data Vault 2.0 approach is allowing teams to democratize access to all their data assets at any scale. We can now easily derive more and more value through insights and intelligence, day after day, bringing businesses to the next level of being truly data-driven. 980 | //Delivering more usable data faster is no longer an option for today's business environment. Using the Snowflake platform, combined with the Data Vault 2.0 architecture it is now possible to build a world class analytics platform that delivers data for all users in near real-time. 981 | 982 | 983 | 984 | ----------------------------------------------------------------------------------- 985 | ----------------------------------------------------------------------------------- 986 | ----------------------------------------------------------------------------------- 987 | 988 | //Option to suspend tasks 989 | ALTER TASK L10_RDV.ORDER_STRM_TSK SUSPEND; 990 | ALTER TASK L10.RDV.CUSTOMER_STRM_TSK SUSPEND; 991 | ALTER TASK L10.RDV.HUB_ORDER_STRM_SAT_ORDER_BV_TSK SUSPEND; 992 | 993 | //Cleanup 994 | USE WAREHOUSE COMPUTE_WH; 995 | DROP DATABASE DV_TUTORIAL; 996 | DROP WAREHOUSE DV_GENERIC_WH; 997 | DROP WAREHOUSE DV_RDV_WH; 998 | -------------------------------------------------------------------------------- /Supplemental Material/Snowflake Connectors for Salesforce Analytics Studio.sql: -------------------------------------------------------------------------------- 1 | //Youtube Video: 2 | 3 | --My Youtube Channel: youtube.com/c/joycekayavila 4 | 5 | --Link to the specific video associated with this tutorial: https://youtu.be/UYFXIwRBB1I 6 | 7 | 8 | 9 | ----------------------------------------------------------------------------------- 10 | ----------------------------------------------------------------------------------- 11 | ----------------------------------------------------------------------------------- 12 | 13 | 14 | //PREWORK 15 | 16 | //Note: for simplicity, the ACCOUNTADMIN and SYSADMIN roles will be used for this tutorial as well as the CREATE OR REPLACE option 17 | --but this would not likely be the case in a real production environment, especially for service accounts. There are several best 18 | --practices that we're not following in this example, for the sake of being able to quickly demonstrate the main topic. 19 | 20 | //Set Context 21 | USE ROLE SYSADMIN; 22 | USE WAREHOUSE COMPUTE_WH; 23 | 24 | //Create Virtual Warehouses 25 | --for the Service Accounts 26 | --and grant usage to SYSADMIN 27 | CREATE OR REPLACE WAREHOUSE SVC1_WH WITH WAREHOUSE_SIZE = XSMALL 28 | AUTO_SUSPEND = 300 AUTO_RESUME = TRUE INITIALLY_SUSPENDED = TRUE; 29 | GRANT USAGE ON WAREHOUSE SVC1_WH TO ROLE SYSADMIN; 30 | CREATE OR REPLACE WAREHOUSE SVC2_WH WITH WAREHOUSE_SIZE = XSMALL 31 | AUTO_SUSPEND = 300 AUTO_RESUME = TRUE INITIALLY_SUSPENDED = TRUE; 32 | GRANT USAGE ON WAREHOUSE SVC2_WH TO ROLE SYSADMIN; 33 | CREATE OR REPLACE WAREHOUSE SVC3_WH WITH WAREHOUSE_SIZE = XSMALL 34 | AUTO_SUSPEND = 300 AUTO_RESUME = TRUE INITIALLY_SUSPENDED = TRUE; 35 | GRANT USAGE ON WAREHOUSE SVC3_WH TO ROLE SYSADMIN; 36 | CREATE OR REPLACE WAREHOUSE SVC4_WH WITH WAREHOUSE_SIZE = XSMALL 37 | AUTO_SUSPEND = 300 AUTO_RESUME = TRUE INITIALLY_SUSPENDED = TRUE; 38 | GRANT USAGE ON WAREHOUSE SVC4_WH TO ROLE SYSADMIN; 39 | 40 | 41 | //Set Context 42 | USE ROLE ACCOUNTADMIN; 43 | USE WAREHOUSE COMPUTE_WH; 44 | 45 | //Create Service Account Users with Defaults 46 | --Example shown for one Service Account User 47 | --Create four service account users in total 48 | CREATE OR REPLACE USER SVC1_USER 49 | PASSWORD='123' 50 | MUST_CHANGE_PASSWORD=FALSE; 51 | GRANT ROLE ACCOUNTADMIN TO USER SVC1_USER; 52 | ALTER USER SVC1_USER SET DEFAULT_WAREHOUSE = SVC1_WH; 53 | ALTER USER SVC1_USER SET DEFAULT_ROLE = SYSADMIN; 54 | 55 | CREATE OR REPLACE USER SVC2_USER 56 | PASSWORD='123' 57 | MUST_CHANGE_PASSWORD=FALSE; 58 | GRANT ROLE ACCOUNTADMIN TO USER SVC2_USER; 59 | ALTER USER SVC2_USER SET DEFAULT_WAREHOUSE = SVC2_WH; 60 | ALTER USER SVC2_USER SET DEFAULT_ROLE = SYSADMIN; 61 | 62 | CREATE OR REPLACE USER SVC3_USER 63 | PASSWORD='123' 64 | MUST_CHANGE_PASSWORD=FALSE; 65 | GRANT ROLE ACCOUNTADMIN TO USER SVC3_USER; 66 | ALTER USER SVC3_USER SET DEFAULT_WAREHOUSE = SVC3_WH; 67 | ALTER USER SVC3_USER SET DEFAULT_ROLE = SYSADMIN; 68 | 69 | CREATE OR REPLACE USER SVC4_USER 70 | PASSWORD='123' 71 | MUST_CHANGE_PASSWORD=FALSE; 72 | GRANT ROLE ACCOUNTADMIN TO USER SVC4_USER; 73 | ALTER USER SVC4_USER SET DEFAULT_WAREHOUSE = SVC4_WH; 74 | ALTER USER SVC4_USER SET DEFAULT_ROLE = SYSADMIN; 75 | 76 | 77 | //Set Context 78 | USE ROLE SYSADMIN; 79 | USE WAREHOUSE COMPUTE_WH; 80 | 81 | //Create database and four schemas 82 | CREATE OR REPLACE DATABASE SFDC; 83 | CREATE OR REPLACE SCHEMA SFDC.SCHEMA1; 84 | CREATE OR REPLACE SCHEMA SFDC.SCHEMA2; 85 | CREATE OR REPLACE SCHEMA SFDC.SCHEMA3; 86 | CREATE OR REPLACE SCHEMA SFDC.SCHEMA4; 87 | 88 | //Create one table in each new schema 89 | --Example shown for one table 90 | CREATE OR REPLACE TABLE SFDC.SCHEMA1.TABLE1 91 | (id integer, f_name string, l_name string, zip_code string); 92 | INSERT INTO SFDC.SCHEMA1.TABLE1 (id, f_name, l_name, zip_code) VALUES 93 | (1, 'Arvind', 'Adams', 30301), (2, 'Patricia', 'Barnes', '35005'); 94 | 95 | 96 | CREATE OR REPLACE TABLE SFDC.SCHEMA2.TABLE1 97 | (id integer, f_name string, l_name string, zip_code string); 98 | INSERT INTO SFDC.SCHEMA2.TABLE1 (id, f_name, l_name, zip_code) VALUES 99 | (1, 'Arvind', 'Adams', 30301), (2, 'Patricia', 'Barnes', '35005'); 100 | 101 | 102 | CREATE OR REPLACE TABLE SFDC.SCHEMA3.TABLE1 103 | (id integer, f_name string, l_name string, zip_code string); 104 | INSERT INTO SFDC.SCHEMA3.TABLE1 (id, f_name, l_name, zip_code) VALUES 105 | (1, 'Arvind', 'Adams', 30301), (2, 'Patricia', 'Barnes', '35005'); 106 | 107 | 108 | CREATE OR REPLACE TABLE SFDC.SCHEMA4.TABLE1 109 | (id integer, f_name string, l_name string, zip_code string); 110 | INSERT INTO SFDC.SCHEMA1.TABLE1 (id, f_name, l_name, zip_code) VALUES 111 | (1, 'Arvind', 'Adams', 30301), (2, 'Patricia', 'Barnes', '35005'); 112 | 113 | 114 | 115 | //Set Context 116 | USE ROLE SYSADMIN; 117 | USE WAREHOUSE COMPUTE_WH; 118 | 119 | //Insert more values into Schema2 Table1 120 | INSERT INTO SFDC.SCHEMA2.TABLE1 (id, f_name, l_name, zip_code) VALUES 121 | (3, 'Bobby', 'Carrol', '76012'), (4, 'Eugene', 'Davis', '35005'); 122 | 123 | 124 | 125 | 126 | 127 | //Cleanup 128 | USE ROLE ACCOUNTADMIN; 129 | USE WAREHOUSE COMPUTE_WH; 130 | 131 | DROP USER SVC1_USER; 132 | DROP USER SVC2_USER; 133 | DROP USER SVC3_USER; 134 | DROP USER SVC4_USER; 135 | 136 | DROP WAREHOUSE SVC1_WH; 137 | DROP WAREHOUSE SVC2_WH; 138 | DROP WAREHOUSE SVC3_WH; 139 | DROP WAREHOUSE SVC4_WH; 140 | 141 | DROP DATABASE SFDC; -------------------------------------------------------------------------------- /Supplemental Material/SnowflakeResources: -------------------------------------------------------------------------------- 1 | Snowflake Free Trial signup.snowflake.com 2 | Snowflake Community community.snowflake.com/s/ 3 | Snowflake Developers youtube.com/@snowflakedevelopers 4 | Reddit reddit.com/r/snowflake/ 5 | Snowflake University learn.snowflake.com 6 | User Group Chapters usergroups.snowflake.com/chapters/ 7 | Snowpro Certifications snowflake.com/certifications/ 8 | Snowflake Release Notes snowflake.com/blog/category/product-and-technology/release-notes/ 9 | Snowflake Release Notes docs.snowflake.com/en/release-notes 10 | Snowflake 8 Workloads https://www.snowflake.com/en/data-cloud/platform/ 11 | Snowflake Quickstarts https://quickstarts.snowflake.com 12 | --------------------------------------------------------------------------------