├── LICENSE.MD ├── README.md ├── SQLWorkbooks-Wallpaper-and-Posters ├── .DS_Store ├── Poster US Letter │ ├── Automatic Plan Correction Poster US Letter.pdf │ ├── Disk Based Rowstore Indexes Poster US Letter.pdf │ ├── Finding Top Queries Poster US Letter.pdf │ ├── Read Phenomena and Isolation Levels in SQL Server Poster US Letter.pdf │ ├── SSMS Shortcuts & Secrets Poster US Letter.pdf │ ├── The Case of the Slow Temp Table Poster US Letter.pdf │ └── User Defined Functions US Letter.pdf ├── Wallpapers 1280x1040 │ ├── Automatic Plan Correction 1280x1040.jpg │ ├── Disk Based Rowstore Indexes 1280x1040.jpg │ ├── Finding Top Queries 1280x1024.jpg │ ├── Read Phenomena and Isolation Levels in SQL Server 1280x1040.jpg │ ├── SSMS Shortcuts & Secrets 1280x1024.jpg │ ├── The Case of the Slow Temp Table 1280x1024.jpg │ └── User Defined Functions 1280x1040.jpg ├── Wallpapers 1920x1080 │ ├── Automatic Plan Correction 1920x1080.jpg │ ├── Disk Based Rowstore Indexes 1920x1080.jpg │ ├── Finding Top Queries 1920x1080.jpg │ ├── Read Phenomena and Isolation Levels in SQL Server 1920x1080.jpg │ ├── SSMS Shortcuts & Secrets 1920x1080.jpg │ ├── The Case of the Slow Temp Table 1920x1080.jpg │ └── User Defined Functions 1920x1080.jpg └── Wallpapers 3440x1440 │ ├── Automatic Plan Correction 3440x1440.jpg │ ├── Disk Based Rowstore Indexes 3440x1440.jpg │ ├── Finding Top Queries 3440x1440.jpg │ ├── Read Phenomena and Isolation Levels in SQL Server 3440x1440.jpg │ ├── SSMS Shortcuts & Secrets 3440x1440.jpg │ ├── The Case of the Slow Temp Table 3440x1440.jpg │ └── User Defined Functions 3440x1440.jpg ├── a_dynamic_sql_challenge ├── A-Dynamic-SQLChallenge_00-Setup.sql ├── A-Dynamic-SQLChallenge_01-Problem.sql └── A-Dynamic-SQLChallenge_02-Solution.sql ├── automatic_plan_correction ├── Automatic-Plan-Correction-01_Setup.sql ├── Automatic-Plan-Correction-02_Get-a-Correction.sql ├── Automatic-Plan-Correction-03_Live-Demo.sql └── Automatic-Plan-Correction-04_Recompile-Hints-and-AT.sql ├── case_of_the_slow_temp_table ├── Case-of-the-Slow-Temp-Table.sql └── sqlworkbooks-case-of-slow-temp-table-wallpaper-1920x1080.jpg ├── ddl_trigger_challenge ├── Who-Made-Schema-Change-DDL-Trigger_00-Setup.sql ├── Who-Made-Schema-Change-DDL-Trigger_01-Challenge.sql └── Who-Made-Schema-Change-DDL-Trigger_02-Solution.sql ├── decipher_cxpacket_tune_parallelism ├── 00-Setup.sql ├── 01-Configuring-MAXDOP.sql ├── 02-Cost-Threshold-for-Parallelism.sql ├── 03-Forcing-parallelism.sql ├── 04-Tuning-Cost-Threshold.sql ├── 05-Parallelism-Killers-and-Inhibitors.sql ├── 06-NUMA.sql ├── 07-CXPACKET-and-CXCONSUMER-Waits.sql ├── maxdop-waits-large-query.xlsx └── maxdop-waits-small-query.xlsx ├── deduplicating_indexes_sqlchallenge ├── Deduplicating-Indexes-Level-1_01-Problem.sql └── Deduplicating-Indexes-Level-1_02-Solutions.sql ├── defuse_deadlock_sqlchallenge ├── DeadlockGraph.xdl ├── Deadlock_Problem.sql ├── Deadlock_Solution.sql └── DefuseTheDeadlockLiveTalk │ ├── DefuseTheDeadlockDemo.sql │ └── DefuseTheDeadlock_slides.pdf ├── dirty_secrets_of_NOLOCK └── Dirty-Secrets-of-NOLOCK.sql ├── event_notifications_challenge ├── Who-Made-Schema-Change-Event-Notification_00-Setup.sql ├── Who-Made-Schema-Change-Event-Notification_01-Challenge.sql └── Who-Made-Schema-Change-Event-Notification_02-Solution.sql ├── execution_plans_partitioning_columnstore ├── 01_Setup_Reading-Execution-Plans-Partitioned-Tables-Columnstore-Indexes.sql ├── 02-Demo-Reading-Execution-Plans-Partitioned-Tables-Columnstore-Indexes.sql ├── 03-Batch-mode-hacks.sql └── partitioning-columnstore-reference-wallpaper-1920-1080.jpg ├── forcing_parallelism_sqlchallenge ├── ForcingParallelism_01_Problem.sql └── ForcingParallelism_02_Solutions.sql ├── how_index_keys_and_includes_work └── How-Keys-and-Included-Columns-Work.sql ├── how_to_decode_memory_pressure ├── MP_00_Restore-Database.sql ├── MP_01_Memory-settings.sql ├── MP_02_Memory-usage-buffer-pool-query-workspace.sql ├── MP_03_Memory-usage-plan-cache.sql └── MP_04_Resource-Governor.sql ├── index_one_year_wonders_sqlchallenge ├── 01_Index-One-Year-Wonders_SQLChallenge_Problem.sql ├── 02_Index-One-Year-Wonders_SQLChallenge_Level-1-Solutions.sql └── 03_Index-One-Year-Wonders_SQLChallenge_Levels-2-and-3-Solutions.sql ├── indexing_for_windowing_functions └── Indexing-for-Windowing-Functions.sql ├── itempotent_tsql_challenge ├── 01_setup-recreate Northwind.sql ├── 02_Idempotent-Query-Challenge.ipynb └── 03_Idempotent-Query-Solutions.ipynb ├── learn_indexing_by_solving_problems ├── 0_RestoreDatabase.sql ├── Topic-2_Nonclustered-Key-Choice_Problem.sql ├── Topic-2_Nonclustered-Key-Choice_Solution.sql ├── Topic-3_Keys-vs-Includes_Problem.sql ├── Topic-3_Keys-vs-Includes_Solution.sql ├── Topic-4_Indexing-Top-Order-By_Problem.sql ├── Topic-4_Indexing-Top-Order-By_Solution.sql ├── Topic-5_Indexing-a-Non-SARGABLE-Column_Problem.sql ├── Topic-5_Indexing-a-Non-SARGABLE-Column_Solution.sql ├── Topic-6_Indexing-for-Group-By_Problem.sql ├── Topic-6_Indexing-for-Group-By_Solution.sql ├── Topic-7_Choosing-Between-Similar-Indexes_Problem.sql ├── Topic-7_Choosing-Between-Similar-Indexes_Solution.sql ├── Topic-8_Comparing-Plans-Between-Two-Clustered-Tables_Problem.sql ├── Topic-8_Comparing-Plans-Between-Two-Clustered-Tables_Solution.sql ├── Topic-9_Indexing-Untamed-Server_Problem.sql ├── Topic-9_Indexing-Untamed-Server_Setup.sql └── Topic-9_Indexing-Untamed-Server_Solution.sql ├── query_tuning_hints_optimizer_hotfixes ├── 001-Setup.sql ├── 002-Table-and-Query-Hints.sql ├── 003-Recompile-Hints.ps1 ├── 003-Recompile-Hints.sql ├── 004-Bumping-Plans-Out-of-Cache.sql └── 005-Query-Optimizer-Hotfixes.sql ├── query_writing_most_unique_names ├── Most-Unique-Names_00-Setup.sql ├── Most-Unique-Names_01-Challenge.sql └── Most-Unique-Names_02-Solution.sql ├── query_writing_peak_year ├── PeakYear_00_Restore-Database.sql ├── PeakYear_01_Challenge.sql └── PeakYear_02_Solution.sql ├── rcsi_and_snapshot_isolation └── RCSI-and-Snapshot-Isolation.sql ├── read_committed_is_bonkers └── Read-Committed-is-Bonkers.sql ├── repeatable_read_and_serializable_isolation_levels └── Repeatable-Read-and-Serializable.sql ├── snapshot_isolation_against_availability_group_secondaries └── Snapshot-Isolation-Against-AG-Secondaries.sql ├── speed_up_popular_names_sqlchallenge ├── Speed-Up-This-Query_Popular-Names_01_Problem.sql └── Speed-Up-This-Query_Popular-Names_02_Solution.sql ├── ssms_shortcuts_and_secrets ├── 00-Setup.sql ├── 01-Open-Sessions-and-Execute-Queries.sql ├── 02-Write-and-Edit-TSQL.sql ├── 03-Use-Object-Explorer-Details.sql ├── 04-Work-With-Execution-Plans.sql ├── 05-Extended-Events.sql ├── 06-SSMS-Diagnostics.sql ├── 07-Stupid-Pet-Tricks.sql ├── SQLWorkbooks-SSMS-Shortcuts-and-Secrets-Cheat-Sheet.pdf └── sqlworkbooks-ssms-shortcuts-secrets-wallpaper_1920-1080.jpg ├── table_partitioning_performance └── Why-Table-Partitioning-Does-Not-Speed-Up-Query-Performance_Demo.sql ├── troubleshooting_blocking_and_deadlocks_for_beginners ├── 00-Setup.sql ├── 01-Blocking-Basics.sql ├── 02-Using-the-Blocked-Process-Report.sql ├── 03-Deadlock-Basics.sql └── 04-Cleanup.sql ├── tuning_a_stored_procedure ├── Tuning-a-Stored-Procedure_01-Problem.sql └── Tuning-a-Stored-Procedure_02-Solution.sql ├── tuning_problem_queries_table_partitioning ├── 00-Setup.sql ├── 01-Aggregator.sql ├── 02-Min_Max.sql └── 03-Blocked.sql ├── why_creating_an_index_can_slow_down_a_query ├── 01-query-tuning-challenge-problem.sql ├── 02-query-tuning-challenge-solution.sql ├── actual-plan-after-adding-index.sqlplan └── actual-plan-before-adding-index.sqlplan └── xevents_sqlchallenge ├── 01_Extended-Events_Problem.sql └── 02_Extended-Events_Solution.sql /LICENSE.MD: -------------------------------------------------------------------------------- 1 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 2 | 3 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 4 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # SQLWorkbooks - Free courses at LittleKendra.com 2 | Free courses to learn SQL Server from https://littlekendra.com/courses 3 | -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/.DS_Store: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/.DS_Store -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Automatic Plan Correction Poster US Letter.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Automatic Plan Correction Poster US Letter.pdf -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Disk Based Rowstore Indexes Poster US Letter.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Disk Based Rowstore Indexes Poster US Letter.pdf -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Finding Top Queries Poster US Letter.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Finding Top Queries Poster US Letter.pdf -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Read Phenomena and Isolation Levels in SQL Server Poster US Letter.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/Read Phenomena and Isolation Levels in SQL Server Poster US Letter.pdf -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/SSMS Shortcuts & Secrets Poster US Letter.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/SSMS Shortcuts & Secrets Poster US Letter.pdf -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/The Case of the Slow Temp Table Poster US Letter.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/The Case of the Slow Temp Table Poster US Letter.pdf -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/User Defined Functions US Letter.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Poster US Letter/User Defined Functions US Letter.pdf -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Automatic Plan Correction 1280x1040.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Automatic Plan Correction 1280x1040.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Disk Based Rowstore Indexes 1280x1040.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Disk Based Rowstore Indexes 1280x1040.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Finding Top Queries 1280x1024.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Finding Top Queries 1280x1024.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Read Phenomena and Isolation Levels in SQL Server 1280x1040.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/Read Phenomena and Isolation Levels in SQL Server 1280x1040.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/SSMS Shortcuts & Secrets 1280x1024.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/SSMS Shortcuts & Secrets 1280x1024.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/The Case of the Slow Temp Table 1280x1024.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/The Case of the Slow Temp Table 1280x1024.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/User Defined Functions 1280x1040.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1280x1040/User Defined Functions 1280x1040.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Automatic Plan Correction 1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Automatic Plan Correction 1920x1080.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Disk Based Rowstore Indexes 1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Disk Based Rowstore Indexes 1920x1080.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Finding Top Queries 1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Finding Top Queries 1920x1080.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Read Phenomena and Isolation Levels in SQL Server 1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/Read Phenomena and Isolation Levels in SQL Server 1920x1080.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/SSMS Shortcuts & Secrets 1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/SSMS Shortcuts & Secrets 1920x1080.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/The Case of the Slow Temp Table 1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/The Case of the Slow Temp Table 1920x1080.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/User Defined Functions 1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 1920x1080/User Defined Functions 1920x1080.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Automatic Plan Correction 3440x1440.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Automatic Plan Correction 3440x1440.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Disk Based Rowstore Indexes 3440x1440.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Disk Based Rowstore Indexes 3440x1440.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Finding Top Queries 3440x1440.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Finding Top Queries 3440x1440.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Read Phenomena and Isolation Levels in SQL Server 3440x1440.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/Read Phenomena and Isolation Levels in SQL Server 3440x1440.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/SSMS Shortcuts & Secrets 3440x1440.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/SSMS Shortcuts & Secrets 3440x1440.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/The Case of the Slow Temp Table 3440x1440.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/The Case of the Slow Temp Table 3440x1440.jpg -------------------------------------------------------------------------------- /SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/User Defined Functions 3440x1440.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/SQLWorkbooks-Wallpaper-and-Posters/Wallpapers 3440x1440/User Defined Functions 3440x1440.jpg -------------------------------------------------------------------------------- /a_dynamic_sql_challenge/A-Dynamic-SQLChallenge_00-Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/a-dynamic-sqlchallenge/ 7 | 8 | SETUP FILE: A Dynamic SQL Challenge 9 | This script creates multiple databases 10 | Note: if the databases already exist, THEY WILL BE DROPPED AND RECREATED 11 | 12 | SQLChallengeDB1 13 | SQLChallengeDB2 14 | SQLChallengeDB3 15 | SQLChallengeDB4 16 | SQLChallengeDB5 17 | *****************************************************************************/ 18 | USE master; 19 | GO 20 | 21 | IF DB_ID('SQLChallengeDB1') IS NOT NULL 22 | BEGIN 23 | USE master; 24 | 25 | ALTER DATABASE SQLChallengeDB1 SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 26 | DROP DATABASE SQLChallengeDB1; 27 | END; 28 | 29 | CREATE DATABASE SQLChallengeDB1; 30 | GO 31 | 32 | IF DB_ID('SQLChallengeDB2') IS NOT NULL 33 | BEGIN 34 | USE master; 35 | 36 | ALTER DATABASE SQLChallengeDB2 SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 37 | DROP DATABASE SQLChallengeDB2; 38 | END; 39 | 40 | CREATE DATABASE SQLChallengeDB2; 41 | GO 42 | 43 | IF DB_ID('SQLChallengeDB3') IS NOT NULL 44 | BEGIN 45 | USE master; 46 | 47 | ALTER DATABASE SQLChallengeDB3 SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 48 | DROP DATABASE SQLChallengeDB3; 49 | END; 50 | 51 | CREATE DATABASE SQLChallengeDB3; 52 | GO 53 | 54 | IF DB_ID('SQLChallengeDB4') IS NOT NULL 55 | BEGIN 56 | USE master; 57 | 58 | ALTER DATABASE SQLChallengeDB4 SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 59 | DROP DATABASE SQLChallengeDB4; 60 | END; 61 | 62 | CREATE DATABASE SQLChallengeDB4; 63 | GO 64 | 65 | 66 | IF DB_ID('SQLChallengeDB5') IS NOT NULL 67 | BEGIN 68 | USE master; 69 | 70 | ALTER DATABASE SQLChallengeDB5 SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 71 | DROP DATABASE SQLChallengeDB5; 72 | END; 73 | 74 | CREATE DATABASE SQLChallengeDB5; 75 | GO 76 | 77 | USE SQLChallengeDB1; 78 | GO 79 | CREATE PROCEDURE dbo.CallMeMaybe @p1 INT 80 | AS 81 | BEGIN 82 | SELECT DB_NAME(), 83 | @p1; 84 | END; 85 | GO 86 | 87 | USE SQLChallengeDB2; 88 | GO 89 | CREATE PROCEDURE dbo.CallMeMaybe @p1 INT 90 | AS 91 | BEGIN 92 | SELECT DB_NAME(), 93 | @p1; 94 | END; 95 | GO 96 | 97 | USE SQLChallengeDB3; 98 | GO 99 | CREATE PROCEDURE dbo.CallMeMaybe @p1 INT 100 | AS 101 | BEGIN 102 | SELECT DB_NAME(), 103 | @p1; 104 | END; 105 | GO 106 | 107 | 108 | USE SQLChallengeDB4; 109 | GO 110 | CREATE PROCEDURE dbo.CallMeMaybe @p1 INT 111 | AS 112 | BEGIN 113 | SELECT DB_NAME(), 114 | @p1; 115 | END; 116 | GO 117 | 118 | 119 | USE SQLChallengeDB5; 120 | GO 121 | CREATE PROCEDURE dbo.CallMeMaybe @p1 INT 122 | AS 123 | BEGIN 124 | SELECT DB_NAME(), 125 | @p1; 126 | END; 127 | GO -------------------------------------------------------------------------------- /a_dynamic_sql_challenge/A-Dynamic-SQLChallenge_01-Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/a-dynamic-sqlchallenge/ 7 | 8 | PROBLEM FILE: A Dynamic SQL Challenge 9 | *****************************************************************************/ 10 | 11 | 12 | /* ✋🏻 Doorstop ✋🏻 */ 13 | RAISERROR(N'Did you mean to run the whole thing?', 20, 1) WITH LOG; 14 | GO 15 | 16 | 17 | 18 | /***************************************************************************** 19 | Your SQLChallenge... 20 | 21 | Add variables and code to the following procedure, dbo.loopthroughdbs 22 | This procedure exists ONLY in SQLChallengeDB01 23 | The procedure uses a cursor to loop through each database named SQLChallengeDB% 24 | (You should have SQLChallengeDB01 to SQLChallengeDB05) 25 | In each database, you need to call the dbo.CallMeMaybe proc 26 | We need to pass in the value for the @p1 parameter, 27 | based on @p1 as provided to dbo.loopthroughdbs 28 | You must insert the results into the @results table (this proc will return them at the end) 29 | 30 | You have two sample calls below the proc for testing 31 | 32 | Stretch: Write the solution TWO different ways 33 | Extra stretch: Write the solution THREE different ways 34 | 35 | *****************************************************************************/ 36 | 37 | /* Here is your procedure to modify */ 38 | 39 | USE SQLChallengeDB1; 40 | GO 41 | 42 | --This procedure exists ONLY in SQLChallengeDB1 43 | CREATE OR ALTER PROCEDURE dbo.loopthroughdbs @p1 INT = 1 44 | AS 45 | BEGIN 46 | 47 | /* 48 | Declare more variables here as needed 49 | */ 50 | DECLARE @db sysname; 51 | 52 | DECLARE @results TABLE 53 | ( 54 | db sysname NOT NULL, 55 | p INT NOT NULL 56 | ); 57 | 58 | DECLARE sqlchallengedbcursor CURSOR FAST_FORWARD LOCAL READ_ONLY FOR 59 | SELECT name 60 | FROM sys.databases 61 | WHERE name LIKE 'SQLChallengeDB%'; 62 | 63 | OPEN sqlchallengedbcursor; 64 | 65 | FETCH NEXT FROM sqlchallengedbcursor 66 | INTO @db; 67 | 68 | WHILE @@FETCH_STATUS = 0 69 | BEGIN 70 | 71 | /* 72 | Add code beginning here 73 | We need to call the dbo.CallMeMaybe proc in each database 74 | For each execution, we want to provide the value for the @p1 parameter, 75 | as passed into this procedure 76 | We want to insert the results into the @results table variable and this proc will return them at the end 77 | */ 78 | 79 | 80 | /* 81 | Add code ending here 82 | */ 83 | 84 | FETCH NEXT FROM sqlchallengedbcursor 85 | INTO @db; 86 | END; 87 | 88 | SELECT db, 89 | p 90 | FROM @results; 91 | 92 | CLOSE sqlchallengedbcursor; 93 | DEALLOCATE sqlchallengedbcursor; 94 | 95 | END; 96 | GO 97 | 98 | EXEC dbo.loopthroughdbs @p1 = 128; 99 | GO 100 | 101 | --Output should look like this after changes are made: 102 | 103 | --db p 104 | --SQLChallengeDB1 128 105 | --SQLChallengeDB2 128 106 | --SQLChallengeDB3 128 107 | --SQLChallengeDB4 128 108 | --SQLChallengeDB5 128 109 | 110 | EXEC dbo.loopthroughdbs @p1 = 2; 111 | GO 112 | 113 | --Output should look like this after changes are made: 114 | 115 | --db p 116 | --SQLChallengeDB1 2 117 | --SQLChallengeDB2 2 118 | --SQLChallengeDB3 2 119 | --SQLChallengeDB4 2 120 | --SQLChallengeDB5 2 -------------------------------------------------------------------------------- /automatic_plan_correction/Automatic-Plan-Correction-01_Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/automatic-plan-correction-in-query-store/ 7 | 8 | Setup: 9 | Download the database to restore from https://github.com/LitKnd/BabbyNames/releases/tag/v1.1 10 | You must download all four backup files with names like 'BabbyNames_Partitioning_1_of_4.bak.zip'. 11 | Unzip each file, then use them to restore the BabbyNames database. 12 | This database is 23GB after being restored. 13 | You must restore to SQL Server 2016 or a higher version. 14 | *****************************************************************************/ 15 | 16 | --RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 17 | --GO 18 | 19 | exec sp_configure 'show advanced options', 1; 20 | GO 21 | RECONFIGURE 22 | GO 23 | exec sp_configure 'cost threshold for parallelism', 50; 24 | GO 25 | exec sp_configure 'max degree of parallelism', 4; 26 | GO 27 | RECONFIGURE 28 | GO 29 | 30 | /******************************************************/ 31 | /* Restore database */ 32 | /******************************************************/ 33 | 34 | /**************************************************** 35 | Restore database and create and populate agg.FirstNameByYearStateWide 36 | ****************************************************/ 37 | SET NOCOUNT, ANSI_NULLS, QUOTED_IDENTIFIER ON 38 | GO 39 | USE master; 40 | GO 41 | 42 | IF DB_ID('BabbyNames') IS NOT NULL 43 | BEGIN 44 | ALTER DATABASE BabbyNames 45 | SET SINGLE_USER 46 | WITH ROLLBACK IMMEDIATE; 47 | END 48 | GO 49 | RESTORE DATABASE BabbyNames 50 | FROM DISK=N'S:\MSSQL\Backup\BabbyNames.bak' 51 | WITH 52 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames.mdf', 53 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames_log.ldf', 54 | REPLACE, 55 | RECOVERY; 56 | GO 57 | 58 | 59 | USE master 60 | GO 61 | ALTER DATABASE BabbyNames SET COMPATIBILITY_LEVEL = 140 62 | GO 63 | 64 | 65 | /* Erin Stellato's recommendations for Query Store Settings are here: 66 | https://www.sqlskills.com/blogs/erin/query-store-settings/ 67 | Don't copy these settings, read Erin's post to understand how to set your own! 68 | */ 69 | ALTER DATABASE BabbyNames SET QUERY_STORE ( 70 | OPERATION_MODE = READ_WRITE, 71 | QUERY_CAPTURE_MODE = AUTO /* default is all, this ignores insignifiant queries */, 72 | MAX_PLANS_PER_QUERY = 200 /*default */, 73 | MAX_STORAGE_SIZE_MB = 2048 /* starter value */, 74 | CLEANUP_POLICY = (STALE_QUERY_THRESHOLD_DAYS = 30), 75 | SIZE_BASED_CLEANUP_MODE = AUTO, 76 | DATA_FLUSH_INTERVAL_SECONDS = 15, 77 | INTERVAL_LENGTH_MINUTES = 30 /* Available values: 1, 5, 10, 15, 30, 60, 1440 */, 78 | WAIT_STATS_CAPTURE_MODE = ON /* 2017 gets wait stats! */ 79 | ); 80 | GO 81 | 82 | ALTER DATABASE BabbyNames SET QUERY_STORE = ON 83 | GO 84 | 85 | ALTER DATABASE BabbyNames 86 | SET AUTOMATIC_TUNING 87 | (FORCE_LAST_GOOD_PLAN = ON) 88 | ; 89 | 90 | USE BabbyNames; 91 | GO 92 | -------------------------------------------------------------------------------- /automatic_plan_correction/Automatic-Plan-Correction-02_Get-a-Correction.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/automatic-plan-correction-in-query-store/ 7 | *****************************************************************************/ 8 | 9 | 10 | USE BabbyNames; 11 | GO 12 | 13 | /* We have some indexes on agg.FirstNameByYear */ 14 | 15 | IF 0 = (SELECT COUNT(*) FROM 16 | sys.indexes 17 | WHERE name='ix_FirstNameByYearState_FirstNameId_StateCode_Gender_ReportYear_INCLUDES') 18 | 19 | CREATE INDEX ix_FirstNameByYearState_FirstNameId_StateCode_Gender_ReportYear_INCLUDES 20 | ON agg.FirstNameByYearState 21 | (FirstNameId, StateCode, Gender, ReportYear) 22 | INCLUDE (NameCount) 23 | GO 24 | 25 | /* OH NO! I created a nonclustered columnstore but left out NameCount, which this query needs. 26 | There are even more problems in the predicates of the procedure, which we're about to create. */ 27 | IF 0 = (SELECT COUNT(*) FROM 28 | sys.indexes 29 | WHERE name='nccx_agg_FirstNameByYearState_oops') 30 | 31 | CREATE NONCLUSTERED COLUMNSTORE INDEX nccx_agg_FirstNameByYearState_oops 32 | on agg.FirstNameByYearState (FirstNameId, StateCode, Gender, ReportYear); 33 | GO 34 | 35 | /* Here is our test procedure. It has some performance problems. */ 36 | CREATE OR ALTER PROCEDURE dbo.PopularNames 37 | @Threshold INT = NULL 38 | AS 39 | SET NOCOUNT ON; 40 | 41 | with RunningTotal AS ( 42 | SELECT 43 | fnby.FirstNameId, 44 | fnby.StateCode, 45 | fnby.Gender, 46 | ReportYear, 47 | SUM(NameCount) OVER (PARTITION BY fnby.FirstNameId, StateCode, Gender ORDER BY fnby.ReportYear) as TotalNamed 48 | FROM agg.FirstNameByYearState as fnby 49 | ), 50 | RunningTotalPlusLag AS ( 51 | SELECT 52 | FirstNameId, 53 | StateCode, 54 | Gender, 55 | ReportYear, 56 | TotalNamed, 57 | LAG(TotalNamed, 1, 0) OVER (PARTITION BY FirstNameId, StateCode, Gender ORDER BY ReportYear) AS TotalNamedPriorYear 58 | FROM RunningTotal 59 | ) 60 | SELECT 61 | fn.FirstName, 62 | RunningTotalPlusLag.StateCode, 63 | RunningTotalPlusLag.Gender, 64 | RunningTotalPlusLag.ReportYear, 65 | RunningTotalPlusLag.TotalNamed, 66 | RunningTotalPlusLag.TotalNamedPriorYear 67 | INTO #results 68 | FROM RunningTotalPlusLag 69 | JOIN ref.FirstName as fn on 70 | RunningTotalPlusLag.FirstNameId=fn.FirstNameId 71 | WHERE 72 | (@Threshold is NULL 73 | and TotalNamed >= 100 74 | and (TotalNamedPriorYear < 100 OR TotalNamedPriorYear IS NULL) 75 | ) 76 | OR 77 | (TotalNamed >= @Threshold 78 | and (TotalNamedPriorYear < @Threshold OR TotalNamedPriorYear IS NULL) 79 | ) 80 | ORDER BY ReportYear DESC, StateCode; 81 | GO 82 | 83 | 84 | DECLARE @msg nvarchar(1000); 85 | SET @msg = cast(sysdatetime() as nvarchar(23)) + N'- FAST PLAN gets batch mode window aggregate operator' 86 | RAISERROR (@msg, 1,1) WITH NOWAIT; 87 | GO 88 | 89 | EXEC dbo.PopularNames @Threshold = 500000; 90 | GO 91 | 92 | EXEC dbo.PopularNames @Threshold = NULL; 93 | GO 94 | 95 | EXEC dbo.PopularNames @Threshold = 200000; 96 | GO 40 97 | 98 | 99 | DECLARE @msg nvarchar(1000); 100 | SET @msg = cast(sysdatetime() as nvarchar(23)) + N'- oh no, a recompile comes along ' 101 | RAISERROR (@msg, 1,1) WITH NOWAIT; 102 | exec sp_recompile 'dbo.PopularNames'; 103 | GO 104 | 105 | 106 | DECLARE @msg nvarchar(1000); 107 | SET @msg = cast(sysdatetime() as nvarchar(23)) + N'- SLOW PLAN gets row mode window spool :( ' 108 | RAISERROR (@msg, 1,1) WITH NOWAIT; 109 | 110 | EXEC dbo.PopularNames @Threshold = NULL; 111 | GO 112 | 113 | EXEC dbo.PopularNames @Threshold = 500000; 114 | GO 115 | 116 | EXEC dbo.PopularNames @Threshold = 600000; 117 | GO 75 118 | 119 | 120 | DECLARE @msg nvarchar(1000); 121 | SET @msg = cast(sysdatetime() as nvarchar(23)) + N'All done!' 122 | RAISERROR (@msg, 1,1) WITH NOWAIT; 123 | -------------------------------------------------------------------------------- /case_of_the_slow_temp_table/sqlworkbooks-case-of-slow-temp-table-wallpaper-1920x1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/case_of_the_slow_temp_table/sqlworkbooks-case-of-slow-temp-table-wallpaper-1920x1080.jpg -------------------------------------------------------------------------------- /ddl_trigger_challenge/Who-Made-Schema-Change-DDL-Trigger_00-Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/who-made-that-schema-change-a-ddl-trigger-sqlchallenge/ 7 | 8 | SQLChallenges are suitable to be run ONLY on private test instances 9 | 10 | SETUP FILE 11 | 12 | This script creates two databases: 13 | * SQLChallengeDDLTriggerWatcher 14 | This database has one table, dbo.DDLWatcher 15 | * SQLChallengeDDLTrigger 16 | 17 | The script also creates a user named [stormy] in the SQLChallengeDDLTrigger database 18 | * This user only has permission in this database 19 | * It has no login, which is weird (and you don't have to create one) 20 | stormy will only be used for testing in the challenge 21 | 22 | 23 | *****************************************************************************/ 24 | 25 | 26 | USE master; 27 | GO 28 | 29 | DROP TRIGGER IF EXISTS DDLWatcher 30 | ON ALL SERVER; 31 | GO 32 | 33 | IF DB_ID('SQLChallengeDDLTriggerWatcher') IS NOT NULL 34 | BEGIN 35 | ALTER DATABASE SQLChallengeDDLTriggerWatcher 36 | SET SINGLE_USER 37 | WITH ROLLBACK IMMEDIATE; 38 | DROP DATABASE SQLChallengeDDLTriggerWatcher; 39 | END; 40 | 41 | CREATE DATABASE SQLChallengeDDLTriggerWatcher; 42 | GO 43 | USE SQLChallengeDDLTriggerWatcher; 44 | GO 45 | 46 | CREATE TABLE dbo.DDLWatcher 47 | ( 48 | RowId BIGINT IDENTITY NOT NULL, 49 | EventType NVARCHAR(128) NULL, 50 | PostTime DATETIME2(0) NULL, 51 | SPID INT NULL, 52 | ServerName NVARCHAR(128) NULL, 53 | LoginName NVARCHAR(128) NULL, 54 | UserName NVARCHAR(128) NULL, 55 | DatabaseName NVARCHAR(128) NULL, 56 | ObjectName NVARCHAR(128) NULL, 57 | NewObjectName NVARCHAR(128) NULL, 58 | ObjectType NVARCHAR(128) NULL, 59 | TSQLCommand NVARCHAR(MAX), 60 | CONSTRAINT pk_DDLWatcher 61 | PRIMARY KEY CLUSTERED (RowId) 62 | ); 63 | 64 | 65 | USE master; 66 | GO 67 | 68 | 69 | IF DB_ID('SQLChallengeDDLTrigger') IS NOT NULL 70 | BEGIN 71 | ALTER DATABASE SQLChallengeDDLTrigger 72 | SET SINGLE_USER 73 | WITH ROLLBACK IMMEDIATE; 74 | DROP DATABASE SQLChallengeDDLTrigger; 75 | END; 76 | 77 | CREATE DATABASE SQLChallengeDDLTrigger; 78 | GO 79 | 80 | --This user is being created for testing only 81 | USE SQLChallengeDDLTrigger; 82 | GO 83 | CREATE USER [stormy] WITHOUT LOGIN; 84 | GO 85 | ALTER ROLE db_datawriter ADD MEMBER [stormy]; 86 | GO 87 | GRANT ALTER TO [stormy]; 88 | GO -------------------------------------------------------------------------------- /ddl_trigger_challenge/Who-Made-Schema-Change-DDL-Trigger_01-Challenge.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/who-made-that-schema-change-a-ddl-trigger-sqlchallenge/ 7 | 8 | SQLChallenges are suitable to be run ONLY on private test instances 9 | 10 | CHALLENGE FILE 11 | 12 | Documentation on DDL Triggers: https://docs.microsoft.com/en-us/sql/relational-databases/triggers/ddl-triggers 13 | Documentation on DDL Events: https://docs.microsoft.com/en-us/sql/relational-databases/triggers/ddl-events 14 | 15 | *****************************************************************************/ 16 | 17 | 18 | /* Doorstop */ 19 | RAISERROR(N'Did you mean to run the whole thing?', 20, 1) WITH LOG; 20 | GO 21 | 22 | 23 | USE SQLChallengeDDLTrigger; 24 | GO 25 | 26 | 27 | /***************************************************************************** 28 | CHALLENGE: 29 | 30 | Create a DDL Trigger named DDLWatcher 31 | 32 | The DDLWatcher trigger should record all of the following activity to a table 33 | in the SQLChallengeDDLTriggerWatcher database, named 34 | dbo.DDLWatcher 35 | This table was created by the setup script 36 | 37 | Note that the activity you'll be logging takes places in the 38 | SQLChallengeDDLTrigger database 39 | 40 | The trigger should log activity for these types of commands if they are run 41 | in ANY database on the instance 42 | (we are simply testing in SQLChallengeDDLTrigger) 43 | 44 | You do not need to log activity for any other types of commands 45 | 46 | *****************************************************************************/ 47 | 48 | 49 | 50 | 51 | /***************************************************************************** 52 | Activity to test (inital rounds) 53 | Each of these six actions should be logged to a table in the SQLChallengeDDLTriggerWatcher datababase 54 | 55 | Note: The entire set of commands is re-runnable 56 | *****************************************************************************/ 57 | 58 | 59 | USE SQLChallengeDDLTrigger; 60 | GO 61 | 62 | CREATE TABLE dbo.watchmego 63 | ( 64 | col1 INT, 65 | col2 CHAR(3) 66 | ); 67 | GO 68 | 69 | ALTER TABLE dbo.watchmego ADD col3 BIT CONSTRAINT df_watchmego DEFAULT 1; 70 | GO 71 | 72 | ALTER TABLE dbo.watchmego DROP CONSTRAINT df_watchmego; 73 | GO 74 | 75 | ALTER TABLE dbo.watchmego DROP COLUMN col3; 76 | GO 77 | 78 | EXEC sp_rename @objname = 'dbo.watchmego', @newname = 'watchmegone'; 79 | GO 80 | 81 | DROP TABLE dbo.watchmegone; 82 | GO 83 | 84 | 85 | 86 | /***************************************************************************** 87 | Activity to test (final round) 88 | 89 | This is the same set of commands from the first round 90 | This time, however, the commands are run from the context of user = stormy 91 | stormy only has permissions in the SQLChallengeDDLTrigger database 92 | 93 | You need to get your DDL trigger to work without explicitly changing permissions for stormy 94 | (you can change permissions on the trigger or on the table, you just 95 | want to use a pattern that doesn't require you to set permissions for 96 | each user who may cause the trigger to fire on the instance) 97 | *****************************************************************************/ 98 | 99 | USE SQLChallengeDDLTrigger; 100 | GO 101 | 102 | EXEC AS USER = 'stormy'; 103 | GO 104 | 105 | SELECT USER_NAME() AS USER_NAME, 106 | SUSER_NAME() AS SUSER_NAME; 107 | 108 | CREATE TABLE dbo.watchmego 109 | ( 110 | col1 INT, 111 | col2 CHAR(3) 112 | ); 113 | GO 114 | 115 | ALTER TABLE dbo.watchmego ADD col3 BIT CONSTRAINT df_watchmego DEFAULT 1; 116 | GO 117 | 118 | ALTER TABLE dbo.watchmego DROP CONSTRAINT df_watchmego; 119 | GO 120 | 121 | ALTER TABLE dbo.watchmego DROP COLUMN col3; 122 | GO 123 | 124 | EXEC sp_rename @objname = 'dbo.watchmego', @newname = 'watchmegone'; 125 | GO 126 | 127 | DROP TABLE dbo.watchmegone; 128 | GO 129 | 130 | --Go back to our normal user 131 | REVERT; 132 | GO 133 | 134 | SELECT USER_NAME() AS USER_NAME, 135 | SUSER_NAME() AS SUSER_NAME; 136 | GO 137 | 138 | 139 | -------------------------------------------------------------------------------- /decipher_cxpacket_tune_parallelism/02-Cost-Threshold-for-Parallelism.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/how-to-decipher-cxpacket-waits-and-control-parallelism 7 | 8 | *****************************************************************************/ 9 | 10 | /* ✋🏻 Doorstop ✋🏻 */ 11 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 12 | GO 13 | 14 | 15 | 16 | 17 | --Let's run at 5 on this demo 18 | exec sp_configure 'max degree of parallelism', 5; 19 | GO 20 | 21 | RECONFIGURE 22 | GO 23 | 24 | /************************************************************ 25 | Configuring cost threshold for parallelism 26 | 27 | Instance level: 28 | 5 (default): estimated cost of 5 29 | *************************************************************/ 30 | use master; 31 | GO 32 | 33 | SELECT name, value, value_in_use, is_advanced 34 | FROM sys.configurations 35 | WHERE name = 'cost threshold for parallelism'; 36 | GO 37 | 38 | exec sp_configure 'show advanced options', 1; 39 | GO 40 | 41 | --View items pending reconfiguration 42 | SELECT name, value, value_in_use, is_advanced 43 | FROM sys.configurations 44 | WHERE value <> value_in_use; 45 | GO 46 | 47 | 48 | RECONFIGURE 49 | GO 50 | 51 | --Set this to the default (if you need to) 52 | exec sp_configure 'cost threshold for parallelism', 5; 53 | GO 54 | 55 | RECONFIGURE 56 | GO 57 | 58 | 59 | 60 | /************************************************************ 61 | Look at estimated cost 62 | 63 | Run this query with actual plans. 64 | 65 | View Estimated Subtree Cost on the root operator 66 | This is an estimate, even in an actual plan 67 | *************************************************************/ 68 | USE BabbyNames; 69 | GO 70 | SELECT 71 | fnbd.Gender, 72 | COUNT(*) as SumNameCount 73 | FROM dbo.FirstNameByBirthDate fnbd 74 | JOIN ref.FirstName as fn on 75 | fnbd.FirstNameId = fn.FirstNameId 76 | WHERE 77 | fn.FirstName = 'Jacob' 78 | GROUP BY Gender; 79 | GO 80 | 81 | /* Estimated cost: 547.107 */ 82 | 83 | 84 | /* Set the threshold for parallelsim just above this cost */ 85 | exec sp_configure 'cost threshold for parallelism', 548; 86 | GO 87 | RECONFIGURE 88 | GO 89 | 90 | /* Run this again. 91 | Does it go parallel? 92 | What is the cost? 93 | */ 94 | SELECT 95 | fnbd.Gender, 96 | COUNT(*) as SumNameCount 97 | FROM dbo.FirstNameByBirthDate fnbd 98 | JOIN ref.FirstName as fn on 99 | fnbd.FirstNameId = fn.FirstNameId 100 | WHERE 101 | fn.FirstName = 'Jacob' 102 | GROUP BY Gender; 103 | GO 104 | 105 | 106 | /* Cost threshold refers to the cost for executing the query 107 | with just one core. 108 | 109 | Here is the threshold for this query... */ 110 | SELECT 111 | fnbd.Gender, 112 | COUNT(*) as SumNameCount 113 | FROM dbo.FirstNameByBirthDate fnbd 114 | JOIN ref.FirstName as fn on 115 | fnbd.FirstNameId = fn.FirstNameId 116 | WHERE 117 | fn.FirstName = 'Jacob' 118 | GROUP BY Gender 119 | OPTION (MAXDOP 1); 120 | GO 121 | 122 | 123 | 124 | 125 | exec sp_configure 'cost threshold for parallelism', 1197; 126 | GO 127 | RECONFIGURE 128 | GO 129 | 130 | 131 | /* The cost of executing this single threaded is just under the threshold, 132 | so it will not go parallel. 133 | This takes much longer to execute single threaded! */ 134 | SELECT 135 | fnbd.Gender, 136 | COUNT(*) as SumNameCount 137 | FROM dbo.FirstNameByBirthDate fnbd 138 | JOIN ref.FirstName as fn on 139 | fnbd.FirstNameId = fn.FirstNameId 140 | WHERE 141 | fn.FirstName = 'Jacob' 142 | GROUP BY Gender; 143 | GO 144 | 145 | 146 | /* Lower the threshold by one ... */ 147 | exec sp_configure 'cost threshold for parallelism', 1196; 148 | GO 149 | RECONFIGURE 150 | GO 151 | 152 | 153 | 154 | /* Now the cost for running this single threaded is just OVER the threshold, 155 | so it qualifies to go parallel */ 156 | SELECT 157 | fnbd.Gender, 158 | COUNT(*) as SumNameCount 159 | FROM dbo.FirstNameByBirthDate fnbd 160 | JOIN ref.FirstName as fn on 161 | fnbd.FirstNameId = fn.FirstNameId 162 | WHERE 163 | fn.FirstName = 'Jacob' 164 | GROUP BY Gender; 165 | GO 166 | 167 | 168 | /* Now let's go really high... */ 169 | exec sp_configure 'cost threshold for parallelism', 20000; 170 | GO 171 | RECONFIGURE 172 | GO 173 | 174 | /* Hints you use in the query are included in estatimed costs. 175 | Look at the change in estimated cost after I hint this not-great index. 176 | (Look at estimated plan.)*/ 177 | SELECT 178 | fnbd.Gender, 179 | COUNT(*) as SumNameCount 180 | FROM dbo.FirstNameByBirthDate fnbd WITH (INDEX (ix_FirstNameByBirthDate_Gender)) 181 | JOIN ref.FirstName as fn on 182 | fnbd.FirstNameId = fn.FirstNameId 183 | WHERE 184 | fn.FirstName = 'Jacob' 185 | GROUP BY Gender; 186 | GO 187 | 188 | 189 | /* The cost threshold value for the query is higher than the threshold 190 | (Look at estimated plan.) */ 191 | 192 | 193 | -------------------------------------------------------------------------------- /decipher_cxpacket_tune_parallelism/04-Tuning-Cost-Threshold.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/how-to-decipher-cxpacket-waits-and-control-parallelism 7 | 8 | *****************************************************************************/ 9 | 10 | 11 | /* ✋🏻 Doorstop ✋🏻 */ 12 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 13 | GO 14 | 15 | 16 | /************************************************************ 17 | What should my cost threshold be? 18 | 19 | Start with: What are my query costs, and how long do my queries take? 20 | ************************************************************/ 21 | 22 | 23 | /* The default value of 5 is SUPER low */ 24 | exec sp_configure 'cost threshold for parallelism', 50; 25 | GO 26 | RECONFIGURE 27 | GO 28 | 29 | /* 30 | We can view queries and plans for our top queries by CPU 31 | This queries the execution plan cache 32 | */ 33 | SELECT TOP 20 34 | (SELECT CAST(SUBSTRING(st.text, (qs.statement_start_offset/2)+1, 35 | ((CASE qs.statement_end_offset 36 | WHEN -1 THEN DATALENGTH(st.text) 37 | ELSE qs.statement_end_offset 38 | END 39 | - qs.statement_start_offset)/2) + 1) AS NVARCHAR(MAX)) FOR XML PATH(''),TYPE) AS [TSQL], 40 | CAST(qs.total_worker_time/1000./1000. AS numeric(30,1)) AS [cpu sec], 41 | qs.execution_count AS [# executions], 42 | qs.last_dop /* 2016+ */, 43 | qs.min_dop /* 2016 + */, 44 | qs.max_dop /* 2016+ */, 45 | CASE WHEN execution_count = 0 THEN 0 ELSE 46 | CAST(qs.total_worker_time / execution_count / 1000. / 1000. AS numeric(30,1)) 47 | END AS [avg cpu sec], 48 | CAST(qs.total_elapsed_time/1000./1000. AS numeric(30,1)) AS [elapsed sec], 49 | CASE WHEN execution_count = 0 THEN 0 ELSE 50 | CAST(qs.total_elapsed_time / execution_count / 1000. / 1000. AS numeric(30,1)) 51 | END AS [avg elapsed sec], 52 | qs.total_logical_reads as [logical reads], 53 | CASE WHEN execution_count = 0 THEN 0 ELSE 54 | CAST(qs.total_logical_reads / execution_count AS numeric(30,1)) 55 | END AS [avg logical reads], 56 | qs.total_physical_reads as [physical reads], 57 | CASE WHEN execution_count = 0 THEN 0 ELSE 58 | CAST(qs.total_physical_reads / execution_count AS numeric(30,1)) 59 | END AS [avg physical reads], 60 | qs.total_logical_writes as [writes], 61 | CASE WHEN execution_count = 0 THEN 0 ELSE 62 | CAST(qs.total_logical_writes / execution_count AS numeric(30,1)) 63 | END AS [avg logical writes], 64 | qp.query_plan AS [query execution plan] 65 | FROM sys.dm_exec_query_stats AS qs 66 | OUTER APPLY sys.dm_exec_sql_text (plan_handle) as st 67 | OUTER APPLY sys.dm_exec_query_plan (plan_handle) AS qp 68 | ORDER BY qs.total_worker_time DESC 69 | OPTION (RECOMPILE); 70 | GO 71 | 72 | 73 | /* 74 | More free queries for the plan cache for different versions of SQL Server are available from 75 | Glenn Berry of SQL Skills: https://www.sqlskills.com/blogs/glenn/category/dmv-queries/ 76 | 77 | 78 | Want to use procedures? 79 | A free procedure to query the plan cache: sp_BlitzCache, from Brent Ozar Unlimited 80 | https://github.com/BrentOzarULTD/SQL-Server-First-Responder-Kit/releases 81 | */ 82 | 83 | 84 | exec sp_BlitzCache; 85 | GO 86 | 87 | 88 | exec sp_BlitzCache @Help=1; 89 | GO 90 | 91 | exec sp_BlitzCache @HideSummary=1 92 | GO 93 | 94 | 95 | /* What about Query Store? 96 | You'd think we'd have a column in one of the Query Store DMVs for this, but we don't. 97 | 98 | I thought I was crazy, but Grant Fritchey found the same thing -- 99 | https://www.scarydba.com/2017/02/20/estimated-costs-queries/ 100 | 101 | */ 102 | 103 | 104 | exec sp_BlitzQueryStore @Help = 1; 105 | GO 106 | 107 | exec sp_BlitzQueryStore @DatabaseName='BabbyNames'; 108 | GO -------------------------------------------------------------------------------- /decipher_cxpacket_tune_parallelism/06-NUMA.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/how-to-decipher-cxpacket-waits-and-control-parallelism 7 | 8 | *****************************************************************************/ 9 | 10 | 11 | /* ✋🏻 Doorstop ✋🏻 */ 12 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 13 | GO 14 | 15 | 16 | 17 | --sys.dm_os_sys_info 18 | --SQL Server 2008+ 19 | SELECT 20 | cpu_count, 21 | hyperthread_ratio, /* Longtime confusing column */ 22 | physical_memory_kb / 1024./1024. as physical_memory_GB, /* SQL Server 2012+ */ 23 | max_workers_count, 24 | virtual_machine_type_desc, /* SQL Server 2008 R2 + */ 25 | softnuma_configuration_desc, /* SQL Server 2016+ */ 26 | socket_count, /* SQL Server 2017+ */ 27 | cores_per_socket, /* SQL Server 2017+ */ 28 | numa_node_count /* SQL Server 2017+ */ 29 | FROM sys.dm_os_sys_info; 30 | GO 31 | 32 | 33 | 34 | 35 | --SQL Server 2008+ 36 | --Q: What is node_id 64? 37 | SELECT node_id, 38 | memory_node_id, 39 | cpu_count, 40 | active_worker_count, 41 | avg_load_balance 42 | from sys.dm_os_nodes; 43 | GO 44 | 45 | 46 | --Note SPID 47 | SELECT @@SPID; 48 | GO 49 | --Start up this query 50 | --While it is running, run the query below in another session 51 | USE BabbyNames; 52 | GO 53 | DROP TABLE IF EXISTS dbo.foo; 54 | SELECT 55 | ISNULL(CAST(ROW_NUMBER() OVER (ORDER BY (SELECT 'boop')) AS BIGINT),0) AS FirstNameByBirthDateId, 56 | DATEADD(mi,n.Num * 5.1,CAST('1/1/' + CAST(ReportYear AS CHAR(4)) AS datetime2(0))) as FakeBirthDateStamp, 57 | fn.StateCode, 58 | fn.FirstNameId, 59 | Gender, 60 | CAST(NULL AS TINYINT) as Flag1, 61 | CAST(NULL AS CHAR(1)) as Flag2 62 | INTO dbo.foo 63 | FROM agg.FirstNameByYearState AS fn 64 | CROSS APPLY (select Num from ref.Numbers where Num <= fn.NameCount) AS n 65 | OPTION (MAXDOP 5); 66 | GO 67 | 68 | --Make sure you use the right @@SPID! 69 | SELECT DISTINCT 70 | s.parent_node_id, 71 | t.session_id, 72 | t.scheduler_id, 73 | w.worker_address, 74 | t.task_state, 75 | wt.wait_type, 76 | wt.wait_duration_ms 77 | FROM sys.dm_os_tasks AS t 78 | JOIN sys.dm_os_schedulers AS s on 79 | t.scheduler_id = s.scheduler_id 80 | LEFT JOIN sys.dm_os_workers AS w on 81 | t.worker_address=w.worker_address 82 | LEFT JOIN sys.dm_os_waiting_tasks AS wt on 83 | w.task_address=wt.waiting_task_address 84 | WHERE t.session_id=52 85 | ORDER BY s.parent_node_id; 86 | 87 | 88 | 89 | 90 | 91 | 92 | 93 | 94 | /* Want to disable automatic soft-numa? 95 | 96 | It is disabled by the following statement, plus it requires a restart to take effect 97 | Currently you need to manually disable the SQL Server Agent before running the command 98 | More info here: https://docs.microsoft.com/en-us/sql/t-sql/statements/alter-server-configuration-transact-sql 99 | */ 100 | 101 | ALTER SERVER CONFIGURATION SET SOFTNUMA OFF; 102 | GO 103 | --Restart sequence 104 | 105 | /* sys.dm_os_sys_info will show a different numa_node_count if you succeed */ 106 | SELECT 107 | cpu_count, 108 | hyperthread_ratio, /* Longtime confusing column */ 109 | physical_memory_kb / 1024./1024. as physical_memory_GB, /* SQL Server 2012+ */ 110 | max_workers_count, 111 | virtual_machine_type_desc, /* SQL Server 2008 R2 + */ 112 | softnuma_configuration_desc, /* SQL Server 2016+ */ 113 | socket_count, /* SQL Server 2017+ */ 114 | cores_per_socket, /* SQL Server 2017+ */ 115 | numa_node_count /* SQL Server 2017+ */ 116 | FROM sys.dm_os_sys_info; 117 | GO 118 | 119 | 120 | --Scroll up and rerun the test query and watch the CPUs used 121 | 122 | 123 | 124 | 125 | ALTER SERVER CONFIGURATION SET SOFTNUMA ON; 126 | GO 127 | --Repeat restart sequence 128 | SELECT 129 | cpu_count, 130 | hyperthread_ratio, /* Longtime confusing column */ 131 | physical_memory_kb / 1024./1024. as physical_memory_GB, /* SQL Server 2012+ */ 132 | max_workers_count, 133 | virtual_machine_type_desc, /* SQL Server 2008 R2 + */ 134 | softnuma_configuration_desc, /* SQL Server 2016+ */ 135 | socket_count, /* SQL Server 2017+ */ 136 | cores_per_socket, /* SQL Server 2017+ */ 137 | numa_node_count /* SQL Server 2017+ */ 138 | FROM sys.dm_os_sys_info; 139 | GO 140 | 141 | 142 | -------------------------------------------------------------------------------- /decipher_cxpacket_tune_parallelism/maxdop-waits-large-query.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/decipher_cxpacket_tune_parallelism/maxdop-waits-large-query.xlsx -------------------------------------------------------------------------------- /decipher_cxpacket_tune_parallelism/maxdop-waits-small-query.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/decipher_cxpacket_tune_parallelism/maxdop-waits-small-query.xlsx -------------------------------------------------------------------------------- /deduplicating_indexes_sqlchallenge/Deduplicating-Indexes-Level-1_01-Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/sqlchallenge-deduplicate-indexes-level-1 7 | 8 | SQLChallenge 9 | Deduplicate Indexes: Level 1 10 | 11 | 12 | Prereq: Download Contoso Data Warehouse sample database from: 13 | https://www.microsoft.com/en-us/download/details.aspx?id=18279 14 | 15 | Download file: ContosoBIdemoBAK.exe 16 | 17 | Run the exe, doing so will unzip files to a directory of your choice 18 | Unzipped, you will have the file ContosoRetailDW.bak 19 | Modify the script below to restore it to a SQL Server instance 20 | 21 | 22 | *****************************************************************************/ 23 | 24 | RAISERROR (N'🛑 Did you mean to run the whole thing? 🛑', 20, 1) WITH LOG; 25 | GO 26 | 27 | 28 | /**************************************************** 29 | Restore database 30 | ****************************************************/ 31 | 32 | SET XACT_ABORT, ANSI_NULLS, QUOTED_IDENTIFIER, ANSI_PADDING ON; 33 | GO 34 | SET NOCOUNT ON; 35 | GO 36 | USE master; 37 | GO 38 | 39 | IF DB_ID('ContosoRetailDW') IS NOT NULL 40 | BEGIN 41 | ALTER DATABASE ContosoRetailDW 42 | SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 43 | 44 | DROP DATABASE ContosoRetailDW; 45 | END 46 | 47 | RESTORE DATABASE ContosoRetailDW 48 | FROM DISK = N'S:\MSSQL\Backup\ContosoRetailDW.bak' 49 | WITH 50 | MOVE N'ContosoRetailDW2.0' TO N'S:\MSSQL\Data\ContosoRetailDW.mdf', 51 | MOVE N'ContosoRetailDW2.0_log' TO N'S:\MSSQL\Data\ContosoRetailDW.ldf', 52 | REPLACE, 53 | RECOVERY; 54 | GO 55 | 56 | /* Configure Query Store, in case it comes in handy.*/ 57 | USE master; 58 | GO 59 | ALTER DATABASE ContosoRetailDW SET QUERY_STORE = ON; 60 | GO 61 | ALTER DATABASE ContosoRetailDW SET QUERY_STORE 62 | (OPERATION_MODE = READ_WRITE, DATA_FLUSH_INTERVAL_SECONDS = 300, INTERVAL_LENGTH_MINUTES = 10); 63 | GO 64 | 65 | --Just to save on log size 66 | ALTER DATABASE ContosoRetailDW SET RECOVERY SIMPLE; 67 | GO 68 | 69 | 70 | ALTER DATABASE ContosoRetailDW SET COMPATIBILITY_LEVEL = 140; 71 | GO 72 | 73 | 74 | 75 | /***************************************************************************** 76 | 77 | CHALLENGE: DEDUPLICATING INDEXES (LEVEL 1) 78 | 🔧 SETUP 🔧 79 | 80 | *****************************************************************************/ 81 | 82 | USE ContosoRetailDW; 83 | GO 84 | 85 | CREATE INDEX ix_FactInventory_InventoryKey 86 | ON dbo.FactInventory(InventoryKey); 87 | GO 88 | 89 | CREATE INDEX ix_FactInventory_InventoryKey_INCLUDES 90 | ON dbo.FactInventory(InventoryKey) 91 | INCLUDE(MinDayInStock, MaxDayInStock); 92 | GO 93 | 94 | CREATE INDEX ix_FactInventory_DateKey_InventoryKey_INCLUDES 95 | ON dbo.FactInventory(DateKey) 96 | INCLUDE(InventoryKey, Aging, OnHandQuantity, OnOrderQuantity, SafetyStockQuantity, UnitCost); 97 | GO 98 | 99 | CREATE INDEX ix_FactInventory_DateKey_INCLUDES 100 | ON dbo.FactInventory(DateKey, InventoryKey) 101 | INCLUDE(Aging, OnHandQuantity, OnOrderQuantity, SafetyStockQuantity, UnitCost, LoadDate, DaysInStock); 102 | GO 103 | 104 | CREATE INDEX ix_FactInventory_DateKey_LoadDate_UnitCost 105 | ON dbo.FactInventory(DateKey, LoadDate, UnitCost) 106 | INCLUDE(Aging, OnHandQuantity, OnOrderQuantity); 107 | GO 108 | 109 | CREATE INDEX ix_FactInventory_DateKey_LoadDate 110 | ON dbo.FactInventory(DateKey, LoadDate, UnitCost) 111 | INCLUDE(Aging); 112 | GO 113 | 114 | CREATE INDEX ix_FactInventory_LoadDate_DateKey_UnitCost 115 | ON dbo.FactInventory(LoadDate, DateKey, UnitCost) 116 | INCLUDE(Aging); 117 | GO 118 | 119 | 120 | CREATE INDEX ix_FactInventory_UnitCost_LoadDate_DateKey 121 | ON dbo.FactInventory(UnitCost, LoadDate, DateKey) 122 | INCLUDE(Aging); 123 | GO 124 | 125 | CREATE INDEX ix_FactInventory_CurrencyKey 126 | ON dbo.FactInventory(CurrencyKey); 127 | GO 128 | 129 | 130 | 131 | 132 | /***************************************************************************** 133 | 134 | 💼 CHALLENGE: DEDUPLICATE INDEXES 💼 135 | 136 | Your task is to de-duplicate the indexes on the dbo.FactInventory table 137 | based on their definitions only -- there's no index "usage" stats to 138 | consider this time. 139 | 140 | Consider the indexes created above, along with any indexes on the table that 141 | are restored with the database. 142 | 143 | For indexes you choose to drop: 144 | 145 | * List the drop command for the index 146 | * Note any risks that are associated with dropping the index 147 | 148 | *****************************************************************************/ 149 | -------------------------------------------------------------------------------- /defuse_deadlock_sqlchallenge/DeadlockGraph.xdl: -------------------------------------------------------------------------------- 1 | 2 | 3 | 4 | 5 | 6 | 7 | 8 | 9 | unknown 10 | 11 | 12 | SELECT 13 | COUNT(*) as OrderCount, 14 | SUM(Amount) as TotalAmount 15 | FROM dbo.V_CustomerOrders 16 | WHERE ProductSubcategory like N'Cell%'; 17 | 18 | 19 | 20 | 21 | 22 | unknown 23 | 24 | unknown 25 | 26 | 27 | UPDATE dbo.DimProductSubcategory 28 | SET ProductSubcategoryName = N'Cellphones Accessories' 29 | WHERE ProductSubcategoryName = N'Cell phones Accessories' 30 | ROLLBACK 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | -------------------------------------------------------------------------------- /defuse_deadlock_sqlchallenge/Deadlock_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/defuse-the-deadlock-sqlchallenge 7 | 8 | Prereq: Download Contoso Data Warehouse sample database from: 9 | https://www.microsoft.com/en-us/download/details.aspx?id=18279 10 | 11 | Download file: ContosoBIdemoBAK.exe 12 | Run the exe, doing so will unzip files to a directory of your choice 13 | Unzipped, you will have the file ContosoRetailDW.bak 14 | 15 | Modify the script below to restore it to a SQL Server instance 16 | ***********************************************************************/ 17 | 18 | RAISERROR ( 'Whoops, did you mean to run the whole thing?', 20, 1) WITH LOG; 19 | GO 20 | 21 | /********************************** 22 | Instance configuration I tested with 23 | **********************************/ 24 | exec sp_configure 'show advanced options', 1; 25 | GO 26 | RECONFIGURE; 27 | GO 28 | exec sp_configure 'cost threshold for parallelism', 50; 29 | GO 30 | exec sp_configure 'max degree of parallelism', 4; 31 | GO 32 | exec sp_configure 'max server memory (MB)', 4000; 33 | GO 34 | RECONFIGURE; 35 | GO 36 | 37 | /********************************** 38 | Restore database 39 | **********************************/ 40 | SET XACT_ABORT, ANSI_NULLS, QUOTED_IDENTIFIER, ANSI_PADDING ON; 41 | GO 42 | SET NOCOUNT OFF; 43 | GO 44 | USE master; 45 | GO 46 | 47 | IF DB_ID('ContosoRetailDW') IS NOT NULL 48 | BEGIN 49 | ALTER DATABASE ContosoRetailDW 50 | SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 51 | 52 | DROP DATABASE ContosoRetailDW; 53 | END 54 | 55 | RESTORE DATABASE ContosoRetailDW 56 | FROM DISK = N'S:\MSSQL\Backup\ContosoRetailDW.bak' 57 | WITH 58 | MOVE N'ContosoRetailDW2.0' TO N'S:\MSSQL\Data\ContosoRetailDW.mdf', 59 | MOVE N'ContosoRetailDW2.0_log' TO N'S:\MSSQL\Data\ContosoRetailDW.ldf', 60 | REPLACE, 61 | RECOVERY; 62 | GO 63 | 64 | ALTER DATABASE ContosoRetailDW SET QUERY_STORE = ON 65 | GO 66 | ALTER DATABASE ContosoRetailDW SET QUERY_STORE (OPERATION_MODE = READ_WRITE) 67 | GO 68 | 69 | 70 | 71 | /********************************* 72 | SQLChallenge starts here... 73 | 74 | The challenge contains code to reproduce a deadlock. 75 | 76 | Your challenge: 77 | Create an index to prevent the deadlock from happening 78 | You cannot change any query text or isolation levels 79 | 80 | Extra credit: 81 | Find more than one way to do it 82 | ***********************************/ 83 | 84 | 85 | 86 | USE ContosoRetailDW; 87 | GO 88 | /* Session 1: 89 | Run BEGIN TRAN and the first UPDATE */ 90 | BEGIN TRAN 91 | UPDATE dbo.DimProductCategory 92 | SET ProductCategoryName = N'Cellphones' 93 | WHERE ProductCategoryName = N'Cell phones'; 94 | /* 95 | UPDATE dbo.DimProductSubcategory 96 | SET ProductSubcategoryName = N'Cellphones Accessories' 97 | WHERE ProductSubcategoryName = N'Cell phones Accessories' 98 | ROLLBACK 99 | */ 100 | 101 | 102 | /* Session 2: 103 | Run this SELECT in a new session. 104 | Then return to Session 1 105 | and run the commented out update 106 | and ROLLBACK 107 | */ 108 | USE ContosoRetailDW; 109 | GO 110 | SELECT 111 | COUNT(*) as OrderCount, 112 | SUM(Amount) as TotalAmount 113 | FROM dbo.V_CustomerOrders 114 | WHERE ProductSubcategory like N'Cell%'; 115 | GO 116 | 117 | 118 | 119 | -------------------------------------------------------------------------------- /defuse_deadlock_sqlchallenge/Deadlock_Solution.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/defuse-the-deadlock-sqlchallenge 7 | 8 | ***********************************************************************/ 9 | 10 | 11 | 12 | 13 | 14 | /* This is the SOLUTION file. 15 | Make sure you check out the problem file first :D 16 | 17 | Then scroll down. 18 | Extra returns are in this file to prevent accidental spoilers. 19 | */ 20 | 21 | 22 | 23 | 24 | 25 | 26 | 27 | 28 | 29 | 30 | 31 | 32 | 33 | 34 | 35 | 36 | 37 | 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | /************************************************************* 48 | Solutions 49 | *************************************************************/ 50 | USE ContosoRetailDW; 51 | GO 52 | 53 | /*************************************** 54 | Door #1 55 | ***************************************/ 56 | 57 | /* 58 | This nonclustered index defuses the deadlock, but does leave some blocking 59 | I have chosen to "cover" the query for dbo.DimProductSubcategory 60 | */ 61 | CREATE INDEX ix_DimProductSubcategory_ProductSubcategoryName_INCLUDES 62 | on dbo.DimProductSubcategory 63 | (ProductSubcategoryName) INCLUDE (ProductSubcategoryKey, ProductCategoryKey); 64 | GO 65 | 66 | /* Clean up */ 67 | DROP INDEX ix_DimProductSubcategory_ProductSubcategoryName_INCLUDES on dbo.DimProductSubcategory; 68 | GO 69 | 70 | 71 | 72 | 73 | /*************************************** 74 | Door #2 75 | ***************************************/ 76 | 77 | /* This nonclustered index defuses the deadlock and removes blocking. */ 78 | CREATE INDEX ix_DimProductCategory 79 | on dbo.DimProductCategory (ProductCategoryKey); 80 | GO 81 | 82 | /* We do have near dupliate indexes on DimProductCategory now, however */ 83 | exec sp_helpindex 'DimProductCategory'; 84 | GO 85 | 86 | /* Clean up */ 87 | DROP INDEX ix_DimProductCategory on dbo.DimProductCategory; 88 | GO -------------------------------------------------------------------------------- /defuse_deadlock_sqlchallenge/DefuseTheDeadlockLiveTalk/DefuseTheDeadlock_slides.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/defuse_deadlock_sqlchallenge/DefuseTheDeadlockLiveTalk/DefuseTheDeadlock_slides.pdf -------------------------------------------------------------------------------- /event_notifications_challenge/Who-Made-Schema-Change-Event-Notification_00-Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/who-made-that-schema-change-an-event-notification-sqlchallenge/ 7 | SETUP FILE 8 | 9 | This script creates two databases: 10 | * SQLChallengeEventNotificationWatcher 11 | This database has one table, dbo.DDLWatcher 12 | * SQLChallengeEventNotification 13 | 14 | The script also creates a user named [stormy] in the SQLChallengeEventNotification database 15 | * This user only has permission in this database 16 | * It has no login, which is weird (and you don't have to create one) 17 | stormy will only be used for testing in the challenge 18 | 19 | 20 | *****************************************************************************/ 21 | 22 | USE master; 23 | GO 24 | 25 | IF 26 | ( 27 | SELECT COUNT(*) 28 | FROM sys.server_event_notifications 29 | WHERE name = 'DDLWatcherEN' 30 | ) > 0 31 | BEGIN 32 | DROP EVENT NOTIFICATION DDLWatcherEN 33 | ON SERVER; 34 | END; 35 | GO 36 | 37 | IF DB_ID('SQLChallengeEventNotificationWatcher') IS NOT NULL 38 | BEGIN 39 | ALTER DATABASE SQLChallengeEventNotificationWatcher 40 | SET SINGLE_USER 41 | WITH ROLLBACK IMMEDIATE; 42 | DROP DATABASE SQLChallengeEventNotificationWatcher; 43 | END; 44 | 45 | CREATE DATABASE SQLChallengeEventNotificationWatcher; 46 | GO 47 | USE SQLChallengeEventNotificationWatcher; 48 | GO 49 | 50 | CREATE TABLE dbo.DDLWatcher 51 | ( 52 | RowId BIGINT IDENTITY NOT NULL, 53 | EventType NVARCHAR(128) NULL, 54 | PostTime DATETIME2(0) NULL, 55 | SPID INT NULL, 56 | ServerName NVARCHAR(128) NULL, 57 | LoginName NVARCHAR(128) NULL, 58 | UserName NVARCHAR(128) NULL, 59 | DatabaseName NVARCHAR(128) NULL, 60 | ObjectName NVARCHAR(128) NULL, 61 | NewObjectName NVARCHAR(128) NULL, 62 | ObjectType NVARCHAR(128) NULL, 63 | TSQLCommand NVARCHAR(MAX), 64 | CONSTRAINT pk_DDLWatcher 65 | PRIMARY KEY CLUSTERED (RowId) 66 | ); 67 | 68 | 69 | USE master; 70 | GO 71 | 72 | 73 | IF DB_ID('SQLChallengeEventNotification') IS NOT NULL 74 | BEGIN 75 | ALTER DATABASE SQLChallengeEventNotification 76 | SET SINGLE_USER 77 | WITH ROLLBACK IMMEDIATE; 78 | DROP DATABASE SQLChallengeEventNotification; 79 | END; 80 | 81 | CREATE DATABASE SQLChallengeEventNotification; 82 | GO 83 | 84 | --This user is being created for testing only 85 | USE SQLChallengeEventNotification; 86 | GO 87 | CREATE USER [stormy] WITHOUT LOGIN; 88 | GO 89 | ALTER ROLE db_datawriter ADD MEMBER [stormy]; 90 | GO 91 | GRANT ALTER TO [stormy]; 92 | GO -------------------------------------------------------------------------------- /event_notifications_challenge/Who-Made-Schema-Change-Event-Notification_01-Challenge.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/who-made-that-schema-change-an-event-notification-sqlchallenge/ 7 | 8 | SQLChallenges are suitable to be run ONLY on private test instances 9 | 10 | CHALLENGE FILE 11 | 12 | http://www.sqlservercentral.com/articles/Event+Notifications/68831/ 13 | 14 | 15 | *****************************************************************************/ 16 | 17 | 18 | /* Doorstop */ 19 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 20 | GO 21 | 22 | 23 | /***************************************************************************** 24 | CHALLENGE: 25 | 26 | Create an event notification named DDLWatcherEN, along with any required dependent objects 27 | 28 | The DDLWatcherEN event notification should record all of the following activity to a table 29 | in the SQLChallengeEventNotificationWatcher database, named 30 | dbo.DDLWatcher 31 | This table was created by the setup script 32 | 33 | Note that the activity you'll be logging takes places in the 34 | SQLChallengeEventNotification database 35 | 36 | The trigger should log activity for these types of commands if they are run 37 | in ANY database on the instance 38 | (we are simply testing in SQLChallengeEventNotification) 39 | 40 | You do not need to log activity for any other types of commands 41 | 42 | You do not need to fully automate receiving the event notifications 43 | It's plenty to write code that receives the notifications and adds them to dbo.DDLWatcher when 44 | you run it manually 45 | You do not need to create a job that runs this periodically or make it an activation procedure 46 | (unless you just feel like it) 47 | 48 | *****************************************************************************/ 49 | 50 | 51 | 52 | 53 | /***************************************************************************** 54 | Activity to test (inital rounds) 55 | Each of these six actions should be logged to a table in the SQLChallengeEventNotificationWatcher datababase 56 | 57 | Note: The entire set of commands is re-runnable 58 | *****************************************************************************/ 59 | 60 | 61 | USE SQLChallengeEventNotification; 62 | GO 63 | 64 | CREATE TABLE dbo.watchmego 65 | ( 66 | col1 INT, 67 | col2 CHAR(3) 68 | ); 69 | GO 70 | 71 | ALTER TABLE dbo.watchmego ADD col3 BIT CONSTRAINT df_watchmego DEFAULT 1; 72 | GO 73 | 74 | ALTER TABLE dbo.watchmego DROP CONSTRAINT df_watchmego; 75 | GO 76 | 77 | ALTER TABLE dbo.watchmego DROP COLUMN col3; 78 | GO 79 | 80 | EXEC sp_rename @objname = 'dbo.watchmego', @newname = 'watchmegone'; 81 | GO 82 | 83 | DROP TABLE dbo.watchmegone; 84 | GO 85 | 86 | 87 | 88 | /***************************************************************************** 89 | Activity to test (final round) 90 | 91 | This is the same set of commands from the first round 92 | This time, however, the commands are run from the context of user = stormy 93 | stormy only has permissions in the SQLChallengeEventNotification database 94 | 95 | Does your Event Notification work for stormy? 96 | Or is a change in permissions needed? 97 | *****************************************************************************/ 98 | 99 | USE SQLChallengeEventNotification; 100 | GO 101 | 102 | EXEC AS USER = 'stormy'; 103 | GO 104 | 105 | CREATE TABLE dbo.watchmego 106 | ( 107 | col1 INT, 108 | col2 CHAR(3) 109 | ); 110 | GO 111 | 112 | ALTER TABLE dbo.watchmego ADD col3 BIT CONSTRAINT df_watchmego DEFAULT 1; 113 | GO 114 | 115 | ALTER TABLE dbo.watchmego DROP CONSTRAINT df_watchmego; 116 | GO 117 | 118 | ALTER TABLE dbo.watchmego DROP COLUMN col3; 119 | GO 120 | 121 | EXEC sp_rename @objname = 'dbo.watchmego', @newname = 'watchmegone'; 122 | GO 123 | 124 | DROP TABLE dbo.watchmegone; 125 | GO 126 | 127 | --Go back to our normal user 128 | REVERT 129 | GO 130 | 131 | 132 | -------------------------------------------------------------------------------- /execution_plans_partitioning_columnstore/01_Setup_Reading-Execution-Plans-Partitioned-Tables-Columnstore-Indexes.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: 7 | https://littlekendra.com/course/the-weird-wonderful-world-of-execution-plans-partitioned-tables-columnstore-indexes 8 | 9 | Setup: 10 | Download the database to restore from https://github.com/LitKnd/BabbyNames/releases/tag/v1.1 11 | You must download all four backup files with names like 'BabbyNames_Partitioning_1_of_4.bak.zip'. 12 | Unzip each file, then use them to restore the BabbyNames database (edit the restore command below). 13 | This database is 23GB after being restored. 14 | You must restore to SQL Server 2016 or a higher version. 15 | *****************************************************************************/ 16 | 17 | SET STATISTICS IO, TIME OFF; 18 | GO 19 | SET XACT_ABORT, NOCOUNT, ANSI_NULLS, QUOTED_IDENTIFIER, ANSI_PADDING ON; 20 | GO 21 | 22 | /******************************************************/ 23 | /* Restore database */ 24 | /******************************************************/ 25 | use master; 26 | GO 27 | IF DB_ID('BabbyNames') IS NOT NULL 28 | BEGIN 29 | ALTER DATABASE BabbyNames SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 30 | END 31 | GO 32 | RESTORE DATABASE BabbyNames FROM 33 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_1_of_4.bak', 34 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_2_of_4.bak', 35 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_3_of_4.bak', 36 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_4_of_4.bak' 37 | WITH 38 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames.mdf', 39 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames_log.ldf', 40 | REPLACE, 41 | RECOVERY; 42 | GO 43 | 44 | /* Enable Query Store */ 45 | ALTER DATABASE [BabbyNames] SET QUERY_STORE = ON 46 | GO 47 | ALTER DATABASE [BabbyNames] SET QUERY_STORE 48 | (OPERATION_MODE = READ_WRITE, 49 | CLEANUP_POLICY = (STALE_QUERY_THRESHOLD_DAYS = 180), 50 | MAX_STORAGE_SIZE_MB = 1024 51 | ) 52 | GO 53 | 54 | USE BabbyNames; 55 | GO 56 | 57 | CREATE NONCLUSTERED COLUMNSTORE INDEX nccx_pt_FirstNameByBirthDate_1966_2015 58 | ON pt.FirstNameByBirthDate_1966_2015 59 | (FakeBirthDateStamp, FirstNameByBirthDateId, StateCode, FirstNameId, Gender); 60 | GO 61 | 62 | /* Insert some fake data for 2016 in batches under the "auto compress" limit */ 63 | INSERT pt.FirstNameByBirthDate_1966_2015 (FakeBirthDateStamp, StateCode, FirstNameId, Gender) 64 | SELECT TOP (102399) 65 | DATEADD(year,1,FakeBirthDateStamp), StateCode, FirstNameId, Gender 66 | FROM pt.FirstNameByBirthDate_1966_2015 67 | WHERE FakeBirthDateStamp >= '2015-01-01' and FakeBirthDateStamp < '2016-01-01' 68 | GO 8 69 | 70 | -------------------------------------------------------------------------------- /execution_plans_partitioning_columnstore/partitioning-columnstore-reference-wallpaper-1920-1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/execution_plans_partitioning_columnstore/partitioning-columnstore-reference-wallpaper-1920-1080.jpg -------------------------------------------------------------------------------- /forcing_parallelism_sqlchallenge/ForcingParallelism_01_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/sqlchallenge-forcing-parallelism 7 | 8 | This SQLChallenge uses the free ContosoRetailDW sample database from Microsoft 9 | Download it here: 10 | https://www.microsoft.com/en-us/download/details.aspx?id=18279 11 | 12 | 13 | 14 | *****************************************************************************/ 15 | RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 16 | GO 17 | 18 | 19 | /***************************************************************************** 20 | CHALLENGE 21 | *****************************************************************************/ 22 | SET ANSI_NULLS, QUOTED_IDENTIFIER, ANSI_PADDING, ANSI_WARNINGS, ARITHABORT, CONCAT_NULL_YIELDS_NULL ON; 23 | GO 24 | SET NUMERIC_ROUNDABORT OFF; 25 | GO 26 | 27 | 28 | 29 | /* Restore ContosoRetailDW, a sample database from Microsoft */ 30 | USE master; 31 | GO 32 | IF DB_ID('ContosoRetailDW') IS NOT NULL 33 | BEGIN 34 | ALTER DATABASE ContosoRetailDW 35 | SET SINGLE_USER WITH ROLLBACK IMMEDIATE 36 | END 37 | 38 | RESTORE DATABASE ContosoRetailDW FROM 39 | DISK = N'S:\MSSQL\Backup\ContosoRetailDW.bak' WITH 40 | MOVE N'ContosoRetailDW2.0' TO N'S:\MSSQL14.DEV\MSSQL\DATA\ContosoRetailDW.mdf', 41 | MOVE N'ContosoRetailDW2.0_log' TO N'S:\MSSQL14.DEV\MSSQL\DATA\ContosoRetailDW.ldf', 42 | REPLACE, 43 | STATS = 5; 44 | GO 45 | 46 | /* Raise compat level */ 47 | ALTER DATABASE ContosoRetailDW SET COMPATIBILITY_LEVEL = 140; 48 | GO 49 | 50 | 51 | 52 | 53 | /* Our instance starts with these settings */ 54 | exec sp_configure 'cost threshold for parallelism', 50; 55 | GO 56 | exec sp_configure 'max degree of parallelism', 4; 57 | GO 58 | EXEC sp_configure 'min server memory (MB)', 256; 59 | GO 60 | EXEC sp_configure 'max server memory (MB)', 2000; 61 | GO 62 | RECONFIGURE 63 | GO 64 | 65 | /* Set up Query Store */ 66 | ALTER DATABASE ContosoRetailDW SET QUERY_STORE ( 67 | OPERATION_MODE = READ_WRITE, 68 | QUERY_CAPTURE_MODE = ALL, /* AUTO is often best!*/ 69 | MAX_PLANS_PER_QUERY = 200, 70 | MAX_STORAGE_SIZE_MB = 2048, 71 | CLEANUP_POLICY = (STALE_QUERY_THRESHOLD_DAYS = 30), 72 | SIZE_BASED_CLEANUP_MODE = AUTO, 73 | DATA_FLUSH_INTERVAL_SECONDS = 15, 74 | INTERVAL_LENGTH_MINUTES = 30, 75 | WAIT_STATS_CAPTURE_MODE = ON /* 2017 gets wait stats! */ 76 | ); 77 | GO 78 | 79 | 80 | USE ContosoRetailDW; 81 | GO 82 | 83 | 84 | /* Our problem uses this view */ 85 | CREATE OR ALTER VIEW dbo.V_CustomerData 86 | AS 87 | SELECT 88 | pc.ProductCategoryName, 89 | psc.ProductSubcategoryName AS ProductSubcategory, 90 | p.ProductName AS Product, 91 | c.CustomerKey, 92 | g.RegionCountryName AS Region, 93 | c.BirthDate, 94 | DATEDIFF(dd,BirthDate,GETDATE())/365. as Age, 95 | c.YearlyIncome, 96 | d.CalendarYear, 97 | d.FiscalYear, 98 | d.CalendarMonth AS Month, 99 | f.SalesOrderNumber AS OrderNumber, 100 | f.SalesOrderLineNumber AS LineNumber, 101 | f.SalesQuantity AS Quantity, 102 | f.SalesAmount AS Amount 103 | FROM 104 | dbo.FactOnlineSales f 105 | JOIN dbo.DimDate d ON f.DateKey = d.DateKey 106 | JOIN dbo.DimProduct p ON f.ProductKey = p.ProductKey 107 | JOIN dbo.DimProductSubcategory psc ON p.ProductSubcategoryKey = psc.ProductSubcategoryKey 108 | JOIN dbo.DimProductCategory pc ON psc.ProductCategoryKey = pc.ProductCategoryKey 109 | JOIN dbo.DimCustomer c ON f.CustomerKey = c.CustomerKey 110 | JOIN dbo.DimGeography g ON c.GeographyKey = g.GeographyKey; 111 | GO 112 | 113 | 114 | /* This is our stored procedure */ 115 | CREATE OR ALTER PROCEDURE dbo.TotalSalesByRegionForYear 116 | @CalendarYear INT NULL 117 | AS 118 | SELECT 119 | Region, 120 | CalendarYear, 121 | SUM(Amount) as TotalSales, 122 | MIN(YearlyIncome) as MinYearlyIncome, 123 | MAX(YearlyIncome) as MaxYearlyIncome 124 | FROM dbo.V_CustomerData 125 | WHERE CalendarYear = @CalendarYear 126 | GROUP BY Region, CalendarYear 127 | ORDER BY TotalSales DESC; 128 | GO 129 | 130 | 131 | /* Run this a couple of times. 132 | We've got some income disparity! 133 | 134 | Look at the plan and confirm it goes parallel. 135 | Just for fun: 136 | Look at the actual plan. How many threads does this get?*/ 137 | EXEC dbo.TotalSalesByRegionForYear @CalendarYear = 2007; 138 | GO 139 | 140 | 141 | 142 | /* The lead DBA makes this change */ 143 | exec sp_configure 'cost threshold for parallelism', 200; 144 | GO 145 | RECONFIGURE 146 | GO 147 | 148 | 149 | /* What is our plan and duration now? */ 150 | EXEC dbo.TotalSalesByRegionForYear @CalendarYear = 2007; 151 | GO 152 | 153 | /* Challenge: 154 | Can you get the parallel plan back for the stored procedure -- 155 | 156 | Without changing cost threshold for parallelism 157 | Without changing the stored procedure definition 158 | 159 | Note: There is more than one possible solution 160 | */ 161 | -------------------------------------------------------------------------------- /how_to_decode_memory_pressure/MP_00_Restore-Database.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/how-to-decode-memory-pressure/ 7 | 8 | 🛑 Caution: This script restores of databases and changes system config! 🛑 9 | ☢️ Suitable for dedicated test instances only ☢️ 10 | 11 | This restores the BabbyNames database, download it from: 12 | https://drive.google.com/file/d/1w0ZGZKHq4N7n6eyP5puu63MuSH3o_hWb/view?usp=sharing 13 | 14 | Read through this script and make sure you want to use these settings 15 | You will also likely need to change drive / path information on the restore command 16 | 17 | *****************************************************************************/ 18 | 19 | 20 | use master; 21 | GO 22 | 23 | exec sp_configure 'show advanced options', 1; 24 | GO 25 | RECONFIGURE 26 | GO 27 | 28 | 29 | exec sp_configure 'cost threshold for parallelism', 50; 30 | exec sp_configure 'max degree of parallelism', 4; 31 | exec sp_configure 'max server memory (MB)', 8000; 32 | GO 33 | 34 | RECONFIGURE 35 | GO 36 | 37 | 38 | IF DB_ID('BabbyNames') IS NOT NULL 39 | BEGIN 40 | ALTER DATABASE BabbyNames SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 41 | END 42 | GO 43 | 44 | /* Change drive / folder information as needed */ 45 | RESTORE DATABASE BabbyNames FROM 46 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_1_of_4.bak', 47 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_2_of_4.bak', 48 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_3_of_4.bak', 49 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_4_of_4.bak' 50 | WITH REPLACE; 51 | GO 52 | 53 | ALTER DATABASE BabbyNames SET RECOVERY SIMPLE; 54 | GO 55 | ALTER DATABASE BabbyNames MODIFY FILE (NAME= BabbyNames, SIZE = 30GB); 56 | GO 57 | ALTER DATABASE BabbyNames MODIFY FILE (NAME= BabbyNames_log, SIZE = 20GB); 58 | 59 | GO 60 | -------------------------------------------------------------------------------- /how_to_decode_memory_pressure/MP_03_Memory-usage-plan-cache.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/how-to-decode-memory-pressure/ 7 | 8 | 9 | NOTE: This script is suitable only for dedicated test instances 10 | Commands in this script will cause havoc and hurt performance 11 | *****************************************************************************/ 12 | 13 | exec sp_configure 'optimize for ad hoc workloads', 0; 14 | GO 15 | 16 | RECONFIGURE 17 | GO 18 | 19 | exec sp_configure 'max server memory (MB)', 8000; 20 | GO 21 | RECONFIGURE 22 | GO 23 | 24 | 25 | DBCC FREEPROCCACHE; 26 | GO 27 | 28 | 29 | /* Size of single use adhoc plans in execution plan cache */ 30 | SELECT 31 | objtype, 32 | cacheobjtype, 33 | COUNT(*) as number_plans, 34 | SUM(size_in_bytes)/1024./1024. as [MB] 35 | FROM sys.dm_exec_cached_plans 36 | WHERE usecounts = 1 37 | and objtype = 'Adhoc' 38 | GROUP BY objtype, cacheobjtype; 39 | GO 40 | 41 | 42 | /* Memory clerks view */ 43 | select 44 | type, 45 | name, 46 | pages_kb, 47 | pages_kb /1024. as page_size_mb 48 | from sys.dm_os_memory_clerks 49 | where type in ( 'CACHESTORE_SQLCP', 'CACHESTORE_OBJCP', 'CACHESTORE_OBJCP', 'CACHESTORE_OBJCP') 50 | GO 51 | 52 | /* https://msdn.microsoft.com/en-us/library/cc293624.aspx 53 | Object Plans (CACHESTORE_OBJCP) 54 | Object Plans include plans for stored procedures, functions, and triggers 55 | 56 | SQL Plans (CACHESTORE_SQLCP) 57 | SQL Plans include the plans for adhoc cached plans, autoparameterized plans, and prepared plans. 58 | 59 | Bound Trees (CACHESTORE_OBJCP) 60 | Bound Trees are the structures produced by SQL Server�s algebrizer for views, constraints, and defaults. 61 | 62 | Extended Stored Procedures (CACHESTORE_OBJCP) 63 | Extended Procs (Xprocs) are predefined system procedures, like sp_executeSql and sp_tracecreate, that are defined using a DLL, not using Transact-SQL statements. The cached structure contains only the function name and the DLL name in which the procedure is implemented. 64 | 65 | */ 66 | 67 | 68 | --Let's run some non-parameterized queries. 69 | --While this is running, run the queries above in another session 70 | DECLARE 71 | @dsql NVARCHAR(2000), 72 | @dsql2 NVARCHAR(2000), 73 | @i int = 1; 74 | SET @dsql = N'DECLARE @foo varchar(256) 75 | SELECT @foo = FirstName 76 | FROM ref.FirstName 77 | WHERE FirstNameId = #x#'; 78 | WHILE @i <= 97310 79 | BEGIN 80 | set @dsql2 = REPLACE (@dsql, '#x#', CAST(@i as nvarchar(5))); 81 | EXEC (@dsql2); 82 | SET @i += 1; 83 | END 84 | 85 | --How many plans ended up in cache? 86 | 87 | 88 | /* Explore the queries generating the single use adhoc plans */ 89 | /* In some cases, I have found single use adhoc plans to all come from one or two bits of code. 90 | In those cases, it can be more effective in the long term to fix the code and make it reuse plans 91 | (it's usually an accident that it wasn't properly parameterized that way). */ 92 | SELECT TOP 100 93 | cacheobjtype, 94 | [text] as [sql text], 95 | size_in_bytes/1024. as [KB] 96 | FROM sys.dm_exec_cached_plans 97 | CROSS APPLY sys.dm_exec_sql_text(plan_handle) 98 | WHERE 99 | usecounts = 1 100 | and objtype = 'Adhoc' 101 | ORDER BY [KB] DESC; 102 | GO 103 | 104 | 105 | /* Put single use adhoc plans into context of the whole plan cache */ 106 | /* When 'Optimize for Adhoc Workloads' is enabled, you'll see a row in 107 | this list with objtype=Adhoc, cacheobjtype=Compiled Plan Stub. 108 | Those are the number and size used by the plan "stubs" of queries 109 | that have just run once since the setting was enabled / instance 110 | restart 111 | */ 112 | SELECT 113 | objtype, 114 | cacheobjtype, 115 | SUM(CASE usecounts WHEN 1 THEN 116 | 1 117 | ELSE 0 END ) AS [Count: Single Use Plans], 118 | SUM(CASE usecounts WHEN 1 THEN 119 | size_in_bytes 120 | ELSE 0 END )/1024./1024. AS [MB: Single Use Plans], 121 | COUNT_BIG(*) as [Count: All Plans], 122 | SUM(size_in_bytes)/1024./1024. AS [MB - All Plans] 123 | FROM sys.dm_exec_cached_plans 124 | GROUP BY objtype, cacheobjtype; 125 | GO 126 | 127 | 128 | --Enable this... 129 | exec sp_configure 'optimize for ad hoc workloads', 1; 130 | GO 131 | 132 | RECONFIGURE 133 | GO 134 | 135 | ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; 136 | GO 137 | 138 | 139 | --Let's run those non-parameterized queries again 140 | --While this is running, run the query above that summarizes the plan cache 141 | DECLARE 142 | @dsql NVARCHAR(2000), 143 | @dsql2 NVARCHAR(2000), 144 | @i int = 1; 145 | SET @dsql = N'DECLARE @foo varchar(256) 146 | SELECT @foo = FirstName 147 | FROM ref.FirstName 148 | WHERE FirstNameId = #x#'; 149 | WHILE @i <= 97310 150 | BEGIN 151 | set @dsql2 = REPLACE (@dsql, '#x#', CAST(@i as nvarchar(5))); 152 | EXEC (@dsql2); 153 | SET @i += 1; 154 | END 155 | GO 156 | 157 | --What if I parameterized my query? 158 | 159 | 160 | 161 | --Enable this... 162 | exec sp_configure 'optimize for ad hoc workloads', 0; 163 | GO 164 | 165 | RECONFIGURE 166 | GO 167 | 168 | ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; 169 | GO 170 | 171 | --This is parameterized dynamic sql 172 | DECLARE 173 | @dsql NVARCHAR(2000), 174 | @i int = 1; 175 | SET @dsql = N'DECLARE @foo varchar(256) 176 | SELECT @foo = FirstName 177 | FROM ref.FirstName 178 | WHERE FirstNameId = @i'; 179 | WHILE @i <= 97310 180 | BEGIN 181 | EXEC sp_executesql @dsql, N'@i INT', @i = @i; 182 | SET @i += 1; 183 | END 184 | 185 | --How many times was the plan for this used? 186 | SELECT TOP 10 187 | cacheobjtype, 188 | [text] as [sql text], 189 | size_in_bytes/1024. as [KB] , 190 | usecounts 191 | FROM sys.dm_exec_cached_plans 192 | CROSS APPLY sys.dm_exec_sql_text(plan_handle) 193 | ORDER BY usecounts DESC; 194 | GO 195 | -------------------------------------------------------------------------------- /index_one_year_wonders_sqlchallenge/01_Index-One-Year-Wonders_SQLChallenge_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/design-the-best-index-for-one-year-wonders-sqlchallenge/ 7 | 8 | 9 | Setup: 10 | Download BabbyNames.bak.zip (42 MB database backup) 11 | https://github.com/LitKnd/BabbyNames/releases/tag/1.3 12 | 13 | This database can be restored to SQL Server 2008R2 or higher 14 | This is the PROBLEM File 15 | *****************************************************************************/ 16 | 17 | /* Doorstop */ 18 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 19 | GO 20 | 21 | 22 | 23 | /**************************************************** 24 | Restore database 25 | ****************************************************/ 26 | SET NOCOUNT, ANSI_NULLS, QUOTED_IDENTIFIER ON 27 | GO 28 | 29 | 30 | --Adjust drive / folder locations for the restore 31 | USE master; 32 | GO 33 | IF DB_ID('BabbyNames2017') IS NOT NULL 34 | BEGIN 35 | ALTER DATABASE BabbyNames2017 36 | SET SINGLE_USER 37 | WITH ROLLBACK IMMEDIATE; 38 | END 39 | GO 40 | RESTORE DATABASE BabbyNames2017 41 | FROM DISK=N'S:\MSSQL\Backup\BabbyNames.bak' 42 | WITH 43 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames2017.mdf', 44 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames2017_log.ldf', 45 | REPLACE, 46 | RECOVERY; 47 | GO 48 | 49 | --Query Store is SQL Server 2016+, 50 | --Comment out for lower versions 51 | ALTER DATABASE BabbyNames2017 SET QUERY_STORE = ON 52 | GO 53 | ALTER DATABASE BabbyNames2017 SET QUERY_STORE (OPERATION_MODE = READ_WRITE) 54 | GO 55 | --This command is SQL Server 2017+, adjust for lower versions 56 | ALTER DATABASE BabbyNames2017 SET COMPATIBILITY_LEVEL = 140; 57 | GO 58 | 59 | 60 | 61 | /**************************************************** 62 | SQLChallenge! 63 | ****************************************************/ 64 | 65 | 66 | /* One year wonders */ 67 | 68 | /* Challenge: 69 | 70 | Level 1: design the best disk based nonclustered rowstore index 71 | for the given query-- in this case, "best" is defined as reducing 72 | the number of logical reads as much as possible for the query. 73 | 74 | Design only one index without using any more advanced indexing 75 | features such as filters, views, etc. 76 | 77 | Make no schema changes to the table other than 78 | creating the single nonclustered index. 79 | 80 | Level 2: use a more advanced feature to minimize the number of 81 | logical reads for the query. This may involve a schema change other 82 | than simply creating the index. 83 | 84 | Level 3: use a second more advanced feature to minimize the 85 | number of logical reads for the query, and compare the pros 86 | and cons of this solution with what you designed in Level 2. 87 | This may involve a schema change other than simply creating 88 | the index. 89 | 90 | This "challenge" query is a fast query that would not normally 91 | require customized indexing. The same principles from this 92 | exercise apply to larger tables as well. 93 | 94 | */ 95 | 96 | USE BabbyNames2017; 97 | GO 98 | 99 | --Let's rebuild the clustered PK before we take a baseline. 100 | --This is an offline rebuild because I haven't specified it differently. 101 | ALTER INDEX pk_FirstName_FirstNameId on 102 | ref.FirstName REBUILD 103 | WITH (FILLFACTOR = 100); 104 | GO 105 | 106 | SET STATISTICS IO ON; 107 | GO 108 | SELECT 109 | FirstName, 110 | FirstReportYear as SoloReportYear, 111 | TotalNameCount 112 | FROM ref.FirstName 113 | WHERE 114 | FirstReportYear = LastReportYear 115 | and TotalNameCount > 10 116 | ORDER BY TotalNameCount DESC; 117 | GO 118 | SET STATISTICS IO OFF; 119 | GO 120 | 121 | /* Logical reads: 482 */ 122 | -------------------------------------------------------------------------------- /index_one_year_wonders_sqlchallenge/02_Index-One-Year-Wonders_SQLChallenge_Level-1-Solutions.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/index_one_year_wonders_sqlchallenge/02_Index-One-Year-Wonders_SQLChallenge_Level-1-Solutions.sql -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/0_RestoreDatabase.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | DATABASE INFO 9 | * The database was backed up from SQL Server 2017 RTM+ CU4. It can be restored to SQL Server 2017 or higher. 10 | * We are using an expanded copy of the BabbyNames database. It contains data from 1880 - 2017. 11 | * The restored database takes up 16GB of space.� 12 | 13 | TO RESTORE 14 | 1. Download BabbyNames_Indexing20180503.zip from https://github.com/LitKnd/BabbyNames/releases 15 | 2. Unzip and you will have 4 files which are all part of one backup 16 | 3. Move all four backup files to your favorite directory to restore from 17 | 18 | 4. Modify the script below to use your own drive and file locations to restore and configure the database 19 | 20 | ****************************************/ 21 | 22 | /* These are the settings I use for demos. I have 4 vCPUs on the demo instance */ 23 | exec sp_configure 'show advanced options', 1; 24 | GO 25 | RECONFIGURE 26 | GO 27 | 28 | exec sp_configure 'max degree of parallelism', 4; 29 | GO 30 | exec sp_configure 'cost threshold for parallelism', 5; 31 | GO 32 | RECONFIGURE 33 | GO 34 | 35 | 36 | use master; 37 | GO 38 | 39 | IF DB_ID('BabbyNames') IS NOT NULL 40 | BEGIN 41 | ALTER DATABASE BabbyNames 42 | SET SINGLE_USER 43 | WITH ROLLBACK IMMEDIATE; 44 | END 45 | GO 46 | RESTORE DATABASE BabbyNames FROM 47 | DISK = N'S:\MSSQL\Backup\BabbyNames_Indexing_20180530_1-of-4.bak', /* Change location */ 48 | DISK = N'S:\MSSQL\Backup\BabbyNames_Indexing_20180530_2-of-4.bak', /* Change location */ 49 | DISK = N'S:\MSSQL\Backup\BabbyNames_Indexing_20180530_3-of-4.bak', /* Change location */ 50 | DISK = N'S:\MSSQL\Backup\BabbyNames_Indexing_20180530_4-of-4.bak' /* Change location */ 51 | WITH 52 | MOVE 'BabbyNames' TO 'T:\MSSQL\Data\BabbyNames.mdf', /* Change location */ 53 | MOVE 'BabbyNames_log' TO 'T:\MSSQL\Data\BabbyNames_log.ldf', /* Change location */ 54 | MOVE 'FG1DAT1' TO 'T:\MSSQL\Data\BabbyNames_FG1DAT1.ndf', /* Change location */ 55 | MOVE 'FG1DAT2' TO 'T:\MSSQL\Data\BabbyNames_FG1DAT2.ndf', /* Change location */ 56 | MOVE 'FG1DAT3' TO 'T:\MSSQL\Data\BabbyNames_FG1DAT3.ndf', /* Change location */ 57 | MOVE 'FG1DAT4' TO 'T:\MSSQL\Data\BabbyNames_FG1DAT4.ndf', /* Change location */ 58 | REPLACE, 59 | RECOVERY; 60 | GO -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-2_Nonclustered-Key-Choice_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | 15 | /*******************************************************************/ 16 | /* PROBLEM */ 17 | /* Nonclustered Key Choice */ 18 | /*******************************************************************/ 19 | 20 | 21 | /* You need to make this query use the fewest logical reads possible. 22 | You must create one single-column nonclustered index to do this. 23 | 24 | (No filters, compression, etc. No changing the query. Only one index.) 25 | (No deleting rows or truncating the table.) 26 | */ 27 | 28 | USE BabbyNames; 29 | GO 30 | 31 | /* The query */ 32 | SELECT 33 | fnby.Gender, 34 | fnby.NameCount, 35 | fnby.ReportYear 36 | FROM agg.FirstNameByYear AS fnby 37 | JOIN ref.FirstName AS fn on 38 | fnby.FirstNameId=fn.FirstNameId 39 | WHERE 40 | fn.FirstName = 'Taylor' 41 | and fnby.Gender='F'; 42 | GO 43 | 44 | 45 | 46 | /* 47 | The tables have only these indexes (Clustered PKs) 48 | The indexes already exist, the code is here for your reference 49 | */ 50 | --ALTER TABLE agg.FirstNameByYear 51 | -- ADD CONSTRAINT pk_aggFirstNameByYear PRIMARY KEY CLUSTERED 52 | -- (ReportYear, FirstNameId, Gender); 53 | --GO 54 | 55 | --ALTER TABLE ref.FirstName 56 | -- ADD CONSTRAINT pk_FirstName_FirstNameId PRIMARY KEY CLUSTERED 57 | -- (FirstNameId); 58 | --GO 59 | 60 | 61 | 62 | /* Design your nonclustered index 63 | Here is the syntax in fill-in-the-blank format 64 | */ 65 | 66 | CREATE INDEX ix_onecolumn 67 | ON __________________ /* tablename */ 68 | ( _________________ ) /* key columname */ ; 69 | GO 70 | 71 | 72 | 73 | -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-3_Keys-vs-Includes_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | /*******************************************************************/ 15 | /* PROBLEM */ 16 | /* Keys vs Includes */ 17 | /*******************************************************************/ 18 | 19 | /* Create these two single column indexes */ 20 | USE BabbyNames; 21 | GO 22 | 23 | CREATE INDEX ix_ref_FirstName_FirstName 24 | on ref.FirstName (FirstName); 25 | GO 26 | 27 | CREATE INDEX ix_agg_FirstNameByYear_FirstNameId 28 | ON agg.FirstNameByYear 29 | ( FirstNameId ); 30 | GO 31 | 32 | /* 33 | sYou want to optimize indexes for this query, 34 | which has a LIKE predicate 35 | */ 36 | SELECT 37 | fnby.Gender, 38 | fnby.NameCount, 39 | fnby.ReportYear 40 | FROM agg.FirstNameByYear AS fnby 41 | JOIN ref.FirstName AS fn on 42 | fnby.FirstNameId=fn.FirstNameId 43 | WHERE 44 | fn.FirstName like 'Ta%' 45 | and fnby.Gender='F'; 46 | GO 47 | 48 | /* Can you think of a reason why SQL might not like to use one of these indexes? 49 | What do you think you should change, and why? */ 50 | 51 | 52 | CREATE INDEX ______________________________ 53 | ON ________________ 54 | ( _________ ) /* One or more keys */ 55 | INCLUDE ( _________ ); /* One or more includes (optional) */ 56 | GO 57 | 58 | 59 | 60 | 61 | 62 | 63 | 64 | 65 | -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-4_Indexing-Top-Order-By_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | 15 | 16 | /*******************************************************************/ 17 | /* PROBLEM */ 18 | /* Indexing a procedure for top and order by */ 19 | /*******************************************************************/ 20 | 21 | 22 | /* Your Junior DBA is testing a new stored procedure 23 | It's scanning the index 24 | But it's really fast! 25 | exec dbo.TopBirthDateStampsByName @FirstName='Jacob' 26 | */ 27 | 28 | USE BabbyNames; 29 | GO 30 | 31 | 32 | /* Here's the existing index used by the query ... */ 33 | /* This takes 60-90 seconds to create */ 34 | CREATE INDEX ExistingIndex 35 | ON dbo.FirstNameByBirthDate_2000_2017 36 | ( FakeBirthDateStamp, FirstName ); 37 | GO 38 | 39 | 40 | /* Here's the procedure */ 41 | CREATE OR ALTER PROCEDURE dbo.TopBirthDateStampsByName 42 | @FirstName VARCHAR(256) 43 | AS 44 | SELECT TOP 150 45 | FakeBirthDateStamp 46 | FROM dbo.FirstNameByBirthDate_2000_2017 47 | WHERE 48 | FirstName = @FirstName 49 | ORDER BY FakeBirthDateStamp DESC; 50 | GO 51 | 52 | 53 | /* Here's how she's testing it */ 54 | /* Jacob is the most popular name given between 2001 and 2005 55 | She wanted to make sure it would use the index if it found a lot of rows */ 56 | SET STATISTICS TIME, IO ON; 57 | GO 58 | exec dbo.TopBirthDateStampsByName @FirstName='Jacob'; 59 | GO 60 | SET STATISTICS TIME, IO OFF; 61 | GO 62 | 63 | 64 | 65 | /* Get the actual execution plan */ 66 | exec dbo.TopBirthDateStampsByName @FirstName='Jacob'; 67 | GO 68 | 69 | 70 | 71 | /* You have a goal to tune queries like this so they consistently 72 | execute in a few hundred milliseconds or less. 73 | 74 | What should you tell your Junior DBA about this one? */ 75 | -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-5_Indexing-a-Non-SARGABLE-Column_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | /*******************************************************************/ 15 | /* PROBLEM */ 16 | /* %nom% ! */ 17 | /*******************************************************************/ 18 | 19 | /* There's one column on our table that is usually null. 20 | But *sometimes* it contains a note. 21 | InevitableLOBColumn is NVARCHAR(MAX). 22 | This column is periodically searched with queries like the following.... 23 | */ 24 | 25 | USE BabbyNames; 26 | GO 27 | 28 | SELECT 29 | FakeBirthDateStamp, 30 | FirstNameId, 31 | FirstName, 32 | InevitableLOBColumn 33 | FROM dbo.FirstNameByBirthDate_2000_2017 34 | WHERE 35 | InevitableLOBColumn like '%nom%' 36 | ORDER BY FakeSystemCreateDateTime DESC 37 | GO 38 | 39 | /* Make this query as fast as possible, using the most efficient nonclustered index possible. */ 40 | 41 | 42 | 43 | 44 | /* Baseline */ 45 | SET STATISTICS IO, TIME ON; 46 | GO 47 | SELECT 48 | FakeBirthDateStamp, 49 | FirstNameId, 50 | FirstName, 51 | InevitableLOBColumn 52 | FROM dbo.FirstNameByBirthDate_2000_2017 53 | WHERE 54 | InevitableLOBColumn like '%nom%' 55 | ORDER BY FakeSystemCreateDateTime DESC 56 | GO 57 | SET STATISTICS IO, TIME OFF; 58 | GO 59 | 60 | 61 | 62 | /* Look at the actual execution plan */ 63 | SELECT 64 | FakeBirthDateStamp, 65 | FirstNameId, 66 | FirstName, 67 | InevitableLOBColumn 68 | FROM dbo.FirstNameByBirthDate_2000_2017 69 | WHERE 70 | InevitableLOBColumn like '%nom%' 71 | ORDER BY FakeSystemCreateDateTime DESC 72 | GO 73 | 74 | /* Notice that we don't have a predicate in the scan. 75 | It's deciding to do a separate filter operator this time. */ 76 | 77 | 78 | /* Design your non-clustered index */ 79 | /* No template this time! */ 80 | 81 | 82 | 83 | 84 | 85 | 86 | 87 | 88 | -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-6_Indexing-for-Group-By_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | 15 | /*******************************************************************/ 16 | /* PROBLEM */ 17 | /* Indexing for Group By */ 18 | /*******************************************************************/ 19 | 20 | 21 | /* 22 | Problem: 23 | 24 | The query below searches for names that occur in one year between 2006-2010 25 | Outline the lowest cost strategy to speed up the query 26 | 27 | Rules: 28 | You must use the FirstNameByBirthDate_2000_2017 table 29 | This is a system where name data is constantly being received 30 | It uses SQL Server 2012 Standard Edition (latest Service Pack) 31 | A large volume of names may come in at any time if hospitals are delayed reporting 32 | The query's results must be real-time 33 | You can modify the query, create objects, etc. 34 | 35 | */ 36 | 37 | /* 38 | Note: I'm talking about a solution for SQL Server 2012 but testing on SQL Server 2017. 39 | That's a big no-no, they're NOT going to be the same, even if you tweak 40 | database compat level and cardinality estimation settings. 41 | In reality we'd need to also test this thoroughly on 2012. 42 | */ 43 | 44 | 45 | 46 | USE BabbyNames; 47 | GO 48 | 49 | 50 | /* Run with actual plan, it's going to take a while */ 51 | SET STATISTICS IO, TIME ON; 52 | GO 53 | SELECT TOP 100 54 | FirstName, 55 | COUNT(*) AS NamedThatYear, 56 | MAX(YEAR(FakeBirthDateStamp)) as YearReported 57 | FROM dbo.FirstNameByBirthDate_2000_2017 AS fnbd 58 | GROUP BY 59 | FirstName 60 | HAVING COUNT(DISTINCT YEAR(FakeBirthDateStamp))=1 61 | ORDER BY COUNT(*) DESC, FirstName; 62 | GO 63 | SET STATISTICS IO, TIME OFF; 64 | GO 65 | 66 | 67 | 68 | -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-7_Choosing-Between-Similar-Indexes_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | 15 | 16 | /*******************************************************************/ 17 | /* PROBLEM */ 18 | /* Baby Boomers */ 19 | /*******************************************************************/ 20 | USE BabbyNames; 21 | GO 22 | 23 | /* 24 | The "baby boom" in the United States occurred between 1946 and 1964 25 | 26 | Given the following query and the agg.FirstNameByYear table, 27 | which of the non-clustered indexes will require fewer logical reads? 28 | */ 29 | 30 | SELECT TOP 10 31 | ReportYear, 32 | SUM(NameCount) as TotalBirthsReported 33 | FROM agg.FirstNameByYear 34 | WHERE 35 | ReportYear <= 2000 36 | and Gender='F' 37 | GROUP BY ReportYear 38 | ORDER BY SUM(NameCount) DESC; 39 | GO 40 | 41 | CREATE INDEX [A] 42 | on agg.FirstNameByYear (Gender) 43 | INCLUDE ( ReportYear, FirstNameId, NameCount ); 44 | GO 45 | 46 | CREATE INDEX [B] 47 | on agg.FirstNameByYear (Gender, ReportYear) 48 | INCLUDE ( NameCount ); 49 | GO 50 | 51 | /* agg.FirstNameByYear has no other nonclustered indexes. 52 | It has a clustered primary key on: (ReportYear ASC, FirstNameId ASC, Gender ASC) 53 | */ 54 | 55 | 56 | 57 | 58 | 59 | /*Baseline */ 60 | SET STATISTICS IO, TIME ON; 61 | GO 62 | SELECT TOP 10 63 | ReportYear, 64 | SUM(NameCount) as TotalBirthsReported 65 | FROM agg.FirstNameByYear 66 | WHERE 67 | ReportYear <= 2000 68 | and Gender='F' 69 | GROUP BY ReportYear 70 | ORDER BY SUM(NameCount) DESC; 71 | GO 72 | SET STATISTICS IO, TIME OFF; 73 | GO 74 | 75 | 76 | 77 | /* Actual execution plan */ 78 | SELECT TOP 10 79 | ReportYear, 80 | SUM(NameCount) as TotalBirthsReported 81 | FROM agg.FirstNameByYear 82 | WHERE 83 | ReportYear <= 2000 84 | and Gender='F' 85 | GROUP BY ReportYear 86 | ORDER BY SUM(NameCount) DESC; 87 | GO -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-8_Comparing-Plans-Between-Two-Clustered-Tables_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | /*******************************************************************/ 14 | /* PROBLEM */ 15 | /* Comparing Plans Between Two Clustered Tables */ 16 | /*******************************************************************/ 17 | USE BabbyNames; 18 | GO 19 | 20 | /* Show the two tables */ 21 | 22 | exec sp_help 'agg.FirstNameByYearWide_Natural'; 23 | GO 24 | 25 | exec sp_help 'agg.FirstNameByYearWide_Surrogate'; 26 | GO 27 | 28 | /* The older "Natural" table has a unique clustered index on ReportYear, Gender, FirstNameId */ 29 | /* The new "Surrogate" we're testing has a unique clustered index on an Identity column (Badly named "Id") */ 30 | 31 | 32 | /* The tables are wide, and have a lot of columns for reporting. */ 33 | 34 | 35 | /* We have an important query */ 36 | /* We can't rewrite the query - if we go with the new table, we'll rename objects */ 37 | /* It uses a CTE to find names by rank, then joins back to the table and returns 38 | a lot of columns for #1 ranked names. */ 39 | with NameRank AS ( 40 | SELECT 41 | ROW_NUMBER () OVER (PARTITION BY ReportYear, Gender ORDER BY NameCount DESC) as RankByGenderAndRow, 42 | ReportYear, 43 | Gender, 44 | FirstNameId, 45 | NameCount 46 | FROM agg.FirstNameByYearWide_Natural AS fnby 47 | ) 48 | SELECT 49 | NameRank.ReportYear, NameRank.Gender, fn.FirstName, NameRank.NameCount, 50 | ReportColumn1, ReportColumn2, ReportColumn3, ReportColumn4, ReportColumn5, ReportColumn6, 51 | ReportColumn7, ReportColumn8, ReportColumn9, ReportColumn10, ReportColumn11, ReportColumn12, 52 | ReportColumn13, ReportColumn14, ReportColumn15, ReportColumn16, ReportColumn17, ReportColumn18, 53 | ReportColumn19, ReportColumn20 54 | FROM NameRank 55 | JOIN agg.FirstNameByYearWide_Natural AS fnby on 56 | fnby.FirstNameId=NameRank.FirstNameId and 57 | fnby.Gender=NameRank.Gender and 58 | fnby.ReportYear=NameRank.ReportYear 59 | JOIN ref.FirstName as fn on fnby.FirstNameId=fn.FirstNameId 60 | WHERE RankByGenderAndRow = 1 61 | GO 62 | 63 | 64 | 65 | /* We duplicate over an index that was created for this query */ 66 | /* The index was tailored to the OVER clause of the windowing function: 67 | OVER (PARTITION BY ReportYear, Gender ORDER BY NameCount DESC) 68 | */ 69 | CREATE NONCLUSTERED INDEX ix_FirstNameByYearWide_Natural_ReportYear_Gender_NameCount 70 | ON agg.FirstNameByYearWide_Natural (ReportYear, Gender, NameCount DESC) 71 | GO 72 | 73 | CREATE NONCLUSTERED INDEX ix_FirstNameByYearWide_Surrogate_ReportYear_Gender_NameCount 74 | ON agg.FirstNameByYearWide_Surrogate (ReportYear, Gender, NameCount DESC) 75 | GO 76 | 77 | 78 | /* Problem: What are we missing with our setup and testing of agg.FirstNameByYearWide_Surrogate? 79 | What could go wrong? */ 80 | 81 | 82 | -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-9_Indexing-Untamed-Server_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | 15 | /********************************************************************* 16 | You're tasked with quickly identifying if there's any quick indexing wins to speed up performance 17 | 18 | Run the script Topic-9_Indexing-Untamed-Server_Setup.sql to simulate the workload 19 | 20 | Strategize: 21 | 22 | * Outline what you will do to find out which indexes would make the most difference (if any): 23 | 24 | * Are you concerned about anything your strategy might miss? 25 | 26 | 27 | Extra credit: use any scripts or tools you already have on-hand, or use built in tools to 28 | diagnose the top couple of index potentials, if you have time 29 | 30 | *********************************************************************/ -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-9_Indexing-Untamed-Server_Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | 11 | USE BabbyNames; 12 | GO 13 | 14 | 15 | 16 | IF (SELECT COUNT(*) FROM sys.indexes WHERE name='ix_lazynamer') = 0 17 | CREATE INDEX ix_lazynamer ON dbo.FirstNameByBirthDate_2000_2017 (FakeBirthDateStamp); 18 | GO 19 | IF (SELECT COUNT(*) FROM sys.indexes WHERE name='ix_FirstNameId') = 0 20 | CREATE INDEX ix_FirstNameId ON dbo.FirstNameByBirthDate_2000_2017 (FirstNameId) WHERE (FakeSystemCreateDateTime > '2015-01-01'); 21 | GO 22 | 23 | 24 | IF (SELECT COUNT(*) FROM sys.indexes WHERE name='ix_FirstNameByYear_FirstNameId') = 0 25 | CREATE NONCLUSTERED INDEX ix_FirstNameByYear_FirstNameId ON agg.FirstNameByYear (FirstNameId ASC); 26 | GO 27 | 28 | /* Reset (makes it rerunnable) */ 29 | ALTER DATABASE BabbyNames SET QUERY_STORE CLEAR; 30 | GO 31 | 32 | 33 | CREATE OR ALTER PROCEDURE dbo.NameCountByGender 34 | @gender CHAR(1), 35 | @firstnameid INT 36 | AS 37 | SET NOCOUNT ON; 38 | SELECT 39 | Gender, 40 | SUM(NameCount) as SumNameCount 41 | INTO #foo 42 | FROM agg.FirstNameByYear AS fact 43 | WHERE 44 | (Gender = @gender or @gender IS NULL) 45 | AND 46 | (FirstNameId = @firstnameid or @firstnameid IS NULL) 47 | GROUP BY Gender; 48 | GO 49 | 50 | 51 | /* ~10 seconds */ 52 | DECLARE @garbageint INT, @garbagedt2 DATETIME2(0), @garbagemax NVARCHAR(MAX) 53 | SELECT 54 | @garbageint=fnbd.FirstNameId, 55 | @garbagedt2=fnbd.FakeBirthDateStamp, 56 | @garbagemax=fnbd.InevitableLOBColumn, 57 | @garbagemax=fnbd.FakeCreatedByUser 58 | FROM dbo.FirstNameByBirthDate_2000_2017 AS fnbd 59 | JOIN ref.FirstName AS fn ON fnbd.FirstNameId=fn.FirstNameId 60 | WHERE fn.FirstName = 'Kendrella'; 61 | GO 1001 62 | 63 | 64 | BEGIN TRAN 65 | UPDATE dbo.FirstNameByBirthDate_2000_2017 66 | SET FakeSystemCreateDateTime = GETDATE() 67 | WHERE FirstNameId=100111 68 | AND Gender='F'; 69 | 70 | ROLLBACK TRAN 71 | GO 12 72 | 73 | BEGIN TRAN 74 | UPDATE dbo.FirstNameByBirthDate_2000_2017 75 | SET FakeSystemCreateDateTime = GETDATE() 76 | WHERE FirstNameId=100111 77 | AND Gender='M' OPTION (RECOMPILE); 78 | 79 | ROLLBACK TRAN 80 | GO 10 81 | 82 | /* 15 seconds */ 83 | BEGIN TRAN 84 | UPDATE dbo.FirstNameByBirthDate_2000_2017 85 | SET FakeSystemCreateDateTime = GETDATE() 86 | WHERE FirstNameId=100111; 87 | 88 | ROLLBACK TRAN 89 | GO 13 90 | 91 | 92 | EXEC dbo.NameCountByGender @gender='M', @firstnameid=NULL; 93 | GO 60 94 | 95 | EXEC dbo.NameCountByGender @gender='M', @firstnameid=91864; 96 | GO 30 97 | 98 | IF OBJECT_ID('tempdb..#byebye') IS NOT NULL 99 | DROP TABLE #byebye; 100 | 101 | SELECT 102 | fnby.Gender, 103 | fnby.NameCount, 104 | fnby.ReportYear 105 | INTO #byebye 106 | FROM agg.FirstNameByYear AS fnby 107 | JOIN ref.FirstName AS fn on 108 | fnby.FirstNameId=fn.FirstNameId 109 | WHERE 110 | fn.FirstName = 'Taylor' 111 | and fnby.Gender='F'; 112 | 113 | GO 22 114 | 115 | DECLARE @int INT, @gender CHAR(1) 116 | SELECT 117 | @int=fact.ReportYear, 118 | @gender=fact.Gender, 119 | @int=fact.NameCount 120 | FROM agg.FirstNameByYear AS fact 121 | JOIN ref.FirstName AS dim 122 | ON fact.FirstNameId=dim.FirstNameId 123 | WHERE 124 | fact.Gender = 'M' AND 125 | dim.FirstName = 'Sue'; 126 | GO 15 127 | 128 | DECLARE @bin INT 129 | SELECT 130 | @bin=COUNT(*) 131 | FROM agg.FirstNameByYear AS fact 132 | JOIN ref.FirstName AS dim 133 | ON fact.FirstNameId=dim.FirstNameId 134 | WHERE 135 | fact.Gender = 'M'; 136 | GO 42 137 | 138 | DECLARE @int INT, @gender CHAR(1) 139 | SELECT 140 | @int=fact.ReportYear, 141 | @gender=fact.Gender 142 | FROM agg.FirstNameByYear AS fact 143 | JOIN ref.FirstName AS dim 144 | ON fact.FirstNameId=dim.FirstNameId 145 | WHERE 146 | fact.Gender = 'M'; 147 | GO 21 148 | 149 | IF OBJECT_ID('tempdb..#abyss') IS NOT NULL 150 | DROP TABLE #abyss; 151 | SELECT 152 | NameCount 153 | INTO #abyss 154 | FROM agg.FirstNameByYear 155 | WHERE FirstNameId = 12663 156 | GO 71 157 | 158 | 159 | IF OBJECT_ID('tempdb..#frequentnames') IS NOT NULL 160 | DROP TABLE #frequentnames; 161 | 162 | SELECT 163 | FirstNameId 164 | INTO #frequentnames 165 | FROM agg.FirstNameByYear 166 | WHERE NameCount > 100 167 | GO 56 168 | 169 | IF OBJECT_ID('tempdb..#byebye') IS NOT NULL 170 | DROP TABLE #byebye; 171 | 172 | SELECT 173 | fnby.Gender, 174 | fnby.NameCount, 175 | fnby.ReportYear 176 | INTO #byebye 177 | FROM agg.FirstNameByYear AS fnby 178 | JOIN ref.FirstName AS fn on 179 | fnby.FirstNameId=fn.FirstNameId 180 | WHERE 181 | fn.FirstName = 'Taylor' 182 | and fnby.Gender='F'; 183 | GO 172 184 | 185 | exec sp_recompile 'agg.FirstNameByYear'; 186 | GO 187 | 188 | EXEC dbo.NameCountByGender @gender='M', @firstnameid=91864; 189 | GO 207 190 | 191 | EXEC dbo.NameCountByGender @gender='M', @firstnameid=NULL; 192 | GO 12 193 | 194 | DECLARE @bin INT 195 | SELECT 196 | @bin=COUNT(*) 197 | FROM agg.FirstNameByYear AS fact 198 | JOIN ref.FirstName AS dim 199 | ON fact.FirstNameId=dim.FirstNameId 200 | WHERE 201 | fact.Gender = 'Z'; 202 | GO 65 203 | 204 | DECLARE @int INT, @gender CHAR(1) 205 | SELECT 206 | @int=fact.ReportYear, 207 | @gender=fact.Gender 208 | FROM agg.FirstNameByYear AS fact 209 | JOIN ref.FirstName AS dim 210 | ON fact.FirstNameId=dim.FirstNameId 211 | WHERE 212 | fact.Gender = 'M'; 213 | GO 25 214 | 215 | IF OBJECT_ID('tempdb..#abyss') IS NOT NULL 216 | DROP TABLE #abyss; 217 | SELECT 218 | NameCount 219 | INTO #abyss 220 | FROM agg.FirstNameByYear 221 | WHERE FirstNameId = -1 222 | GO 101 223 | -------------------------------------------------------------------------------- /learn_indexing_by_solving_problems/Topic-9_Indexing-Untamed-Server_Solution.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/learn-indexing-by-solving-problems-sql-seminar-june-2018/ 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | 14 | 15 | /********************************************************************* 16 | We're going to look at this from two perspectives.... 17 | First, Query Store 18 | 19 | Then, plan cache and missing index DMVs 20 | 21 | In each one, we're going to see how we would make our top two index recommendations to test. 22 | 23 | *********************************************************************/ 24 | 25 | 26 | 27 | 28 | /********************************************************************* 29 | Query Store... 30 | If I have SQL Server 2016+ available, I want to test and use this to get 31 | at those juicy execution plans 32 | *********************************************************************/ 33 | 34 | --Query Store isn't on by default 35 | --You need to enable it and configure collection and retention options 36 | --Start light - you control how much data it stores! 37 | --Make sure you have at least CU1 if you're not running enterprise or 38 | -- dev edition, it fixes an important cleanup bug: https://support.microsoft.com/en-us/kb/3178297 39 | 40 | 41 | /* 42 | Open 'Top Resource Consuming Queries' Report 43 | This is a built-in report 44 | Reports show up automagically after Query Store is enabled for the database 45 | 46 | Go to the time period where you care about performance 47 | (The "Configure" button at top right does this) 48 | 49 | Make sure you're on the "Duration - Total" view 50 | 51 | The top query has two plans-- show them 52 | Neither plan is asking for an index 53 | The faster one is *scanning* an NC index. 54 | The nested loop plan is much slower 55 | Hover over the nonclustered index scan 56 | Look at the predicate 57 | Can we get rid of that with an index change? 58 | Hover over the key lookup 59 | Is there a non-seek predicate? 60 | Look at the output list 61 | How can we get rid of the key lookup? 62 | Would this change also prevent the NC index scan plan? 63 | Change to the index scan plan 64 | Look at the predicate and output 65 | 66 | Recommendation for #1 slow query: 67 | Add Gender Key and NameCount included column 68 | to agg.FirstNameByYear.ix_FirstNameByYear_FirstNameId 69 | Gender is already effectively there, but the query needs it, so let's be explicit 70 | Giving it NameCount will eliminate the key lookup and index scan options 71 | 72 | Long term, to make this seekable the code needs a rewrite of one of these flavors to get rid of the "or" logic... 73 | Dynamic SQL 74 | Sub-procedures 75 | */ 76 | 77 | /* Let's look at index usage on the table for a sanity check */ 78 | /* This is the free sp_BlitzIndex procedure from Brent Ozar Unlimited */ 79 | /* If you pass in a database, schema, and index name it lists existing and missing indexes for the table */ 80 | exec sp_BlitzIndex 81 | @DatabaseName='BabbyNames', 82 | @SchemaName='agg', 83 | @TableName='FirstNameByYear'; 84 | GO 85 | 86 | 87 | 88 | /********************************************************************* 89 | If we didn't have Query Store, we'd look at the Plan Cache and Missing Index DMVs... 90 | *********************************************************************/ 91 | 92 | 93 | /* sp_BlitzCache looks at the plan cache. */ 94 | /* This will have info since the instance was restarted, but we don't know what's missing. */ 95 | /* Recompile hints and memory pressure can cause gaps. */ 96 | exec sp_BlitzCache @HideSummary=1; 97 | GO 98 | 99 | 100 | /* #1 Query ... 101 | Look at the top two lines 102 | They're related! 103 | Look at the plan. 104 | Familiar? 105 | 106 | We only see the nested loop plan. Why is that? 107 | Go back to BlitzCache and look at 108 | warnings 109 | average reads 110 | We could decode that we need to add the included column to the index from this as well 111 | It's just harder to figure out 112 | And we don't see that clustered index scan plan 113 | 114 | */ 115 | 116 | /* #2 Query ... 117 | Look at the next line 118 | Familiar? 119 | Same query we saw in querystore... 120 | We can decode the index in the same way. 121 | */ 122 | 123 | /* Here's one of the big problems... */ 124 | /* Let's say something flushes the plan for our #1 procedure out of cache */ 125 | exec sp_recompile 'dbo.NameCountByGender'; 126 | GO 127 | 128 | /* Can we see it here anymore? */ 129 | exec sp_BlitzCache @HideSummary=1; 130 | GO 131 | 132 | 133 | 134 | 135 | /* We can run BlitzIndex with no parameters and have it give us warnings about issues, 136 | including our biggest tables to index. */ 137 | /* Do we see agg.FirstNameByYear warned about in here? */ 138 | exec sp_BlitzIndex; 139 | GO 140 | 141 | /* 142 | That's because that slowest query didn't flag a missing index request... 143 | because of the way the TSQL was written. 144 | If we keep tuning the server and it's slow again, we may find it later in the query plan cache. 145 | It's easier when we track our slowest queries with a tool like Query Store. 146 | */ 147 | 148 | 149 | 150 | /* FYI, this exists! */ 151 | exec sp_BlitzQueryStore @DatabaseName = 'BabbyNames' 152 | GO -------------------------------------------------------------------------------- /query_tuning_hints_optimizer_hotfixes/001-Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/query-tuning-with-hints-optimizer-hotfixes 7 | 8 | Setup: 9 | Download the database to restore from https://github.com/LitKnd/BabbyNames/releases/tag/v1.1 10 | You must download all four backup files with names like 'BabbyNames_Partitioning_1_of_4.bak.zip'. 11 | Unzip each file, then use them to restore the BabbyNames database (edit the restore command below). 12 | This database is 23GB after being restored. 13 | You must restore to SQL Server 2016 or a higher version. 14 | *****************************************************************************/ 15 | 16 | --RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 17 | --GO 18 | 19 | 20 | /******************************************************/ 21 | /* Restore database */ 22 | /******************************************************/ 23 | use master; 24 | GO 25 | IF DB_ID('BabbyNames') IS NOT NULL 26 | BEGIN 27 | ALTER DATABASE BabbyNames SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 28 | END 29 | GO 30 | RESTORE DATABASE BabbyNames FROM 31 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_1_of_4.bak', 32 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_2_of_4.bak', 33 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_3_of_4.bak', 34 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_4_of_4.bak' 35 | WITH REPLACE; 36 | GO 37 | 38 | /* SQL Server 2016+ */ 39 | ALTER DATABASE SCOPED CONFIGURATION SET QUERY_OPTIMIZER_HOTFIXES = OFF; 40 | GO 41 | 42 | ALTER DATABASE SCOPED CONFIGURATION SET LEGACY_CARDINALITY_ESTIMATION = OFF; 43 | GO 44 | 45 | exec sp_configure 'show advanced options', 1; 46 | GO 47 | RECONFIGURE 48 | GO 49 | 50 | exec sp_configure 'max degree of parallelism', 4; 51 | GO 52 | 53 | RECONFIGURE 54 | GO 55 | 56 | 57 | USE BabbyNames; 58 | GO 59 | 60 | 61 | EXEC evt.logme N'Create agg.FirstNameByYearStateWide_Stage.'; 62 | GO 63 | 64 | SELECT 65 | ISNULL(CAST(ROW_NUMBER() OVER (ORDER BY (SELECT 1)) AS bigint),0) AS Id, 66 | ReportYear, 67 | StateCode, 68 | FirstNameId, 69 | Gender, 70 | NameCount, 71 | REPLICATE ('foo',3) AS ReportColumn1, 72 | REPLICATE ('fo',3) AS ReportColumn2, 73 | REPLICATE ('fo',3) AS ReportColumn3, 74 | 1014 AS ReportColumn4, 75 | REPLICATE ('moo',3) AS ReportColumn5, 76 | REPLICATE ('mo',3) AS ReportColumn6, 77 | REPLICATE ('m',300) AS ReportColumn7, 78 | 1 AS ReportColumn8, 79 | 15060902002 AS ReportColumn9, 80 | REPLICATE ('boo',300) AS ReportColumn10, 81 | REPLICATE ('bo',3) AS ReportColumn11, 82 | REPLICATE ('b',30) AS ReportColumn12, 83 | CAST('true' AS BIT) AS ReportColumn13, 84 | 2000000000000 AS ReportColumn14, 85 | CAST ('2016-01-01' AS DATETIME2(7)) AS ReportColumn15, 86 | CAST ('2015-01-01' AS DATETIME2(7)) AS ReportColumn16, 87 | CAST ('2014-01-01' AS DATETIME2(7)) AS ReportColumn17, 88 | CAST ('2013-01-01' AS DATETIME2(7)) AS ReportColumn18, 89 | 14 AS ReportColumn19, 90 | CAST ('You are such a creep to add a LOB column, Kendra' AS NVARCHAR(MAX)) AS ReportColumn20 91 | INTO agg.FirstNameByYearStateWide_Stage 92 | FROM agg.FirstNameByYearState; 93 | GO 94 | 95 | EXEC evt.logme N'Cluster agg.FirstNameByYearStateWide_Stage.'; 96 | GO 97 | 98 | CREATE UNIQUE CLUSTERED INDEX cx_agg_FirstNameByYearStateWide_Stage 99 | ON agg.FirstNameByYearStateWide_Stage ( Id ); 100 | GO 101 | 102 | EXEC evt.logme N'Create agg.FirstNameByYearStateWide, which has an identity property'; 103 | GO 104 | 105 | CREATE TABLE agg.FirstNameByYearStateWide ( 106 | Id bigint IDENTITY NOT NULL, 107 | ReportYear int NOT NULL, 108 | StateCode char(2) NOT NULL, 109 | FirstNameId int NOT NULL, 110 | Gender char(1) NOT NULL, 111 | NameCount int NOT NULL, 112 | ReportColumn1 varchar(9) NULL, 113 | ReportColumn2 varchar(6) NULL, 114 | ReportColumn3 varchar(6) NULL, 115 | ReportColumn4 int NOT NULL, 116 | ReportColumn5 varchar(9) NULL, 117 | ReportColumn6 varchar(6) NULL, 118 | ReportColumn7 varchar(300) NULL, 119 | ReportColumn8 int NOT NULL, 120 | ReportColumn9 numeric(11, 0) NOT NULL, 121 | ReportColumn10 varchar(900) NULL, 122 | ReportColumn11 varchar(6) NULL, 123 | ReportColumn12 varchar(30) NULL, 124 | ReportColumn13 bit NULL, 125 | ReportColumn14 numeric(13, 0) NOT NULL, 126 | ReportColumn15 datetime2(7) NULL, 127 | ReportColumn16 datetime2(7) NULL, 128 | ReportColumn17 datetime2(7) NULL, 129 | ReportColumn18 datetime2(7) NULL, 130 | ReportColumn19 int NOT NULL, 131 | ReportColumn20 nvarchar(max) NULL 132 | ); 133 | GO 134 | 135 | CREATE UNIQUE CLUSTERED INDEX cx_agg_FirstNameByYearStateWide 136 | ON agg.FirstNameByYearStateWide ( Id ); 137 | GO 138 | 139 | EXEC evt.logme N'Switch data from stage'; 140 | GO 141 | 142 | ALTER TABLE agg.FirstNameByYearStateWide_Stage SWITCH TO agg.FirstNameByYearStateWide; 143 | GO 144 | 145 | EXEC evt.logme N'Drop Stage'; 146 | GO 147 | 148 | DROP TABLE agg.FirstNameByYearStateWide_Stage; 149 | GO 150 | 151 | EXEC evt.logme N'Reset the identity value'; 152 | GO 153 | DBCC CHECKIDENT ('agg.FirstNameByYearStateWide'); 154 | GO 155 | 156 | ALTER TABLE agg.FirstNameByYearStateWide 157 | ADD CONSTRAINT 158 | pk_FirstNameByYearStateWide 159 | PRIMARY KEY NONCLUSTERED (ReportYear, StateCode, Gender, FirstNameId) 160 | GO 161 | 162 | 163 | CREATE NONCLUSTERED INDEX ix_FirstNameByYearStateWide_ReportYear_StateCode_Gender_NameCount_Includes 164 | ON agg.FirstNameByYearStateWide (ReportYear, StateCode, Gender, NameCount DESC) INCLUDE ( FirstNameId); 165 | GO 166 | 167 | CREATE NONCLUSTERED COLUMNSTORE INDEX ccx_agg_FirstNameByYearStateWide 168 | ON agg.FirstNameByYearStateWide 169 | (Id, FirstNameId, ReportYear, StateCode, Gender, NameCount); 170 | GO 171 | 172 | CREATE NONCLUSTERED COLUMNSTORE INDEX ccx_agg_FirstNameByYearState 173 | ON agg.FirstNameByYearState 174 | (FirstNameId, ReportYear, StateCode, Gender, NameCount); 175 | GO 176 | -------------------------------------------------------------------------------- /query_tuning_hints_optimizer_hotfixes/003-Recompile-Hints.ps1: -------------------------------------------------------------------------------- 1 | <# 2 | Copyright (c) 2017 SQL Workbooks LLC 3 | Terms of Use: https://sqlworkbooks.com/terms-of-service/ 4 | Contact: help@sqlworkbooks.com 5 | #> 6 | 7 | # This script relies on stored procedures created by 003-Recompile-Hints.sql 8 | # The script also assumes you're using a default SQL Server instance on the local server 9 | # The script was tested on Windows Server 2012 R2 - your mileage may vary on lower versions 10 | 11 | 12 | # Executes a stored procedure a specified amount of times in a loop 13 | # Fills a dataset but does nothing with it - this is only for the purpose 14 | # of watching performance counters while the procedures run. 15 | 16 | function LoopStoredProcedure{ 17 | param($Limit, $Connection, $Procedure, $Parameters=@{}) 18 | 19 | $SqlCmd = New-Object System.Data.SqlClient.SqlCommand 20 | $SqlCmd.CommandType = [System.Data.CommandType]::StoredProcedure 21 | $SqlCmd.Connection = $Connection 22 | $SqlCmd.CommandText = $Procedure 23 | foreach($parameter in $Parameters.Keys){ 24 | [Void] $SqlCmd.Parameters.AddWithValue("@$parameter",$Parameters[$parameter]) 25 | } 26 | 27 | $Iterations=0 28 | while($Iterations -ne $Limit) { 29 | $SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter($SqlCmd) 30 | $DataSet = New-Object System.Data.DataSet 31 | [Void] $SqlAdapter.Fill($DataSet) 32 | 33 | $DataSet.Dispose() 34 | $Iterations++ 35 | } 36 | 37 | $SqlConnection.Close() 38 | return "All done!" 39 | } 40 | 41 | $SqlConnection = New-Object System.Data.SqlClient.SqlConnection 42 | $SqlConnection.ConnectionString = "Server=.;Database=BabbyNames;Integrated Security=True" 43 | 44 | $Duration = Measure-Command { LoopStoredProcedure -Limit 500 -Connection $SqlConnection -Procedure "dbo.MostPopularYearByNameRecompileHint" -Parameters @{FirstName="Mary"}} 45 | Write-Output "Recompile hint = $($Duration.TotalSeconds) seconds" 46 | 47 | $Duration = Measure-Command { LoopStoredProcedure -Limit 500 -Connection $SqlConnection -Procedure "dbo.MostPopularYearByNameRecompileInHeader" -Parameters @{FirstName="Mary"}} 48 | Write-Output "Recompile hint in header = $($Duration.TotalSeconds) seconds" 49 | 50 | $Duration = Measure-Command { LoopStoredProcedure -Limit 500 -Connection $SqlConnection -Procedure "dbo.MostPopularYearByName" -Parameters @{FirstName="Mary"}} 51 | Write-Output "No recompile hint = $($Duration.TotalSeconds) seconds" 52 | -------------------------------------------------------------------------------- /query_tuning_hints_optimizer_hotfixes/003-Recompile-Hints.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/query-tuning-with-hints-optimizer-hotfixes 7 | 8 | *****************************************************************************/ 9 | 10 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 11 | GO 12 | 13 | USE BabbyNames; 14 | GO 15 | 16 | /* Setup................................................ */ 17 | /* WARNING: this clears the ENTIRE execution plan cache */ 18 | DBCC FREEPROCCACHE; 19 | GO 20 | /* ..................................................... */ 21 | 22 | 23 | 24 | /* We're going to watch the performance of the same code: 25 | 1) With a RECOMPILE hint on a statement 26 | 2) With a RECOMPILE hint in the header of the procedure 27 | 3) With no RECOMPILE hint 28 | */ 29 | 30 | 31 | DROP PROCEDURE IF EXISTS dbo.MostPopularYearByNameRecompileHint 32 | GO 33 | CREATE PROCEDURE dbo.MostPopularYearByNameRecompileHint 34 | @FirstName varchar(255) 35 | AS 36 | SET NOCOUNT ON; 37 | 38 | SELECT TOP 1 39 | NameCount 40 | FROM agg.FirstNameByYear AS fnby 41 | JOIN ref.FirstName AS fn on 42 | fnby.FirstNameId = fn.FirstNameId 43 | WHERE fn.FirstName = @FirstName 44 | ORDER BY NameCount DESC 45 | OPTION (RECOMPILE); 46 | GO 47 | 48 | DROP PROCEDURE IF EXISTS dbo.MostPopularYearByNameRecompileInHeader 49 | GO 50 | CREATE PROCEDURE dbo.MostPopularYearByNameRecompileInHeader 51 | @FirstName varchar(255) 52 | WITH RECOMPILE 53 | AS 54 | SET NOCOUNT ON; 55 | 56 | SELECT TOP 1 57 | NameCount 58 | FROM agg.FirstNameByYear AS fnby 59 | JOIN ref.FirstName AS fn on 60 | fnby.FirstNameId = fn.FirstNameId 61 | WHERE fn.FirstName = @FirstName 62 | ORDER BY NameCount DESC; 63 | GO 64 | 65 | DROP PROCEDURE IF EXISTS dbo.MostPopularYearByName 66 | GO 67 | CREATE PROCEDURE dbo.MostPopularYearByName 68 | @FirstName varchar(255) 69 | AS 70 | SET NOCOUNT ON; 71 | 72 | SELECT TOP 1 73 | NameCount 74 | FROM agg.FirstNameByYear AS fnby 75 | JOIN ref.FirstName AS fn on 76 | fnby.FirstNameId = fn.FirstNameId 77 | WHERE fn.FirstName = @FirstName 78 | ORDER BY NameCount DESC; 79 | GO 80 | 81 | 82 | 83 | /* 84 | We're going to run each procedure from powershell 500 times from one thread. 85 | The posh script doesn't do anything with the procedure results, just measures 86 | the time it takes to run the procedure 500 times. 87 | 88 | Open perfmon.exe and show the following counters: 89 | SQL Server: SQL Statistics Batch Requests/sec 90 | SQL Server: SQL Statistics SQL Compilations/sec 91 | SQL Server: SQL Statistics SQL Re-Compilations/sec 92 | 93 | In powershell, run 005-Recompile-Hints.ps1 94 | */ 95 | 96 | /* What can we see about performance in SQL Server's DMVs? */ 97 | /* sys.dm_exec_query_stats has info on performance for queries that 98 | are currently in the execution plan cache. */ 99 | SELECT 100 | (SELECT SUBSTRING(st.text, (qs.statement_start_offset/2)+1, 101 | ((CASE qs.statement_end_offset WHEN -1 THEN DATALENGTH(st.text) ELSE qs.statement_end_offset END 102 | - qs.statement_start_offset)/2) + 1) FOR XML PATH(''),TYPE) AS [query_text], 103 | qs.execution_count, 104 | qs.total_worker_time, 105 | qs.total_logical_reads, 106 | qs.total_elapsed_time, 107 | qp.query_plan 108 | FROM sys.dm_exec_query_stats AS qs 109 | CROSS APPLY sys.dm_exec_sql_text (plan_handle) as st 110 | CROSS APPLY sys.dm_exec_query_plan (plan_handle) AS qp 111 | WHERE st.text like '%MostPopularYearByName%' 112 | OPTION (RECOMPILE); 113 | GO 114 | 115 | 116 | /* sys.dm_exec_procedure_stats has information for performance 117 | on stored procedures that are currently in the execution plan cache */ 118 | SELECT 119 | st.text as procedure_text, 120 | ps.execution_count, 121 | ps.total_worker_time, 122 | ps.total_logical_reads, 123 | ps.total_elapsed_time, 124 | qp.query_plan 125 | FROM sys.dm_exec_procedure_stats AS ps 126 | CROSS APPLY sys.dm_exec_sql_text (plan_handle) as st 127 | CROSS APPLY sys.dm_exec_query_plan (plan_handle) AS qp 128 | JOIN sys.objects as so on ps.object_id = so.object_id 129 | WHERE so.name like 'MostPopularYearByName%' 130 | OPTION (RECOMPILE); 131 | GO 132 | 133 | 134 | -------------------------------------------------------------------------------- /query_tuning_hints_optimizer_hotfixes/004-Bumping-Plans-Out-of-Cache.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/query-tuning-with-hints-optimizer-hotfixes 7 | 8 | *****************************************************************************/ 9 | 10 | 11 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 12 | GO 13 | 14 | /********************************************************** 15 | Setup 16 | **********************************************************/ 17 | USE BabbyNames; 18 | GO 19 | 20 | DROP PROCEDURE IF EXISTS dbo.MostPopularYearByName 21 | GO 22 | CREATE PROCEDURE dbo.MostPopularYearByName 23 | @FirstName varchar(255) 24 | AS 25 | SET NOCOUNT ON; 26 | 27 | SELECT TOP 1 28 | NameCount 29 | FROM agg.FirstNameByYear AS fnby 30 | JOIN ref.FirstName AS fn on 31 | fnby.FirstNameId = fn.FirstNameId 32 | WHERE fn.FirstName = @FirstName 33 | ORDER BY NameCount DESC; 34 | GO 35 | 36 | EXEC dbo.MostPopularYearByName @FirstName = 'Kendra'; 37 | GO 10 38 | 39 | 40 | 41 | 42 | /********************************************************** 43 | Demo 44 | **********************************************************/ 45 | 46 | /* Bump a plan for an individual query. 47 | You can give this a plan_handle or a sql_handle */ 48 | SELECT 49 | qs.plan_handle, 50 | qs.sql_handle, 51 | (SELECT SUBSTRING(st.text, (qs.statement_start_offset/2)+1, 52 | ((CASE qs.statement_end_offset WHEN -1 THEN DATALENGTH(st.text) ELSE qs.statement_end_offset END 53 | - qs.statement_start_offset)/2) + 1) FOR XML PATH(''),TYPE) AS [query_text], 54 | qs.execution_count, 55 | qs.total_worker_time, 56 | qs.total_logical_reads, 57 | qs.total_elapsed_time, 58 | qp.query_plan 59 | FROM sys.dm_exec_query_stats AS qs 60 | CROSS APPLY sys.dm_exec_sql_text (plan_handle) as st 61 | CROSS APPLY sys.dm_exec_query_plan (plan_handle) AS qp 62 | WHERE st.text like '%fnby.FirstNameId = fn.FirstNameId 63 | WHERE fn.FirstName = @FirstName 64 | ORDER BY NameCount DESC;%' 65 | OPTION (RECOMPILE); 66 | GO 67 | 68 | DBCC FREEPROCCACHE (0x0500070012A0AF62C082800B2800000001000000000000000000000000000000000000000000000000000000); 69 | GO 70 | 71 | /* Now re-run the query: poof! */ 72 | 73 | 74 | 75 | 76 | /* You can use the sp_recompile procedure to clear multiple plans from the cache 77 | Warning: this requires a lock on the object you're running against! 78 | I've caused blocking by running this against a table. 79 | */ 80 | EXEC sp_recompile 'dbo.MostPopularYearByName' 81 | GO 82 | 83 | 84 | 85 | 86 | 87 | /* You can clear plan from a resource governor pool */ 88 | SELECT * 89 | FROM sys.dm_resource_governor_resource_pools; 90 | GO 91 | /* I don't have any configured, and default is pretty big... */ 92 | DBCC FREEPROCCACHE ('default'); 93 | GO 94 | 95 | 96 | 97 | 98 | /* You can neatly clear the cache for the current database in 2016+ */ 99 | ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; 100 | GO 101 | 102 | 103 | 104 | 105 | 106 | /* On older versions of SQL Server, you can do this with a DBCC command, but 107 | you have to look up the database id. */ 108 | SELECT DB_ID(); 109 | GO 110 | DBCC FLUSHPROCINDB(7); 111 | GO 112 | 113 | 114 | 115 | 116 | 117 | /* The "nuclear" option. 118 | This clears the whole cache for the instance */ 119 | DBCC FREEPROCCACHE; 120 | GO 121 | 122 | 123 | 124 | 125 | /* There's even more ways to do this out there like DBCC FREESYSTEMCACHE, 126 | but what I've shown here is usually more than enough for me! */ -------------------------------------------------------------------------------- /query_tuning_hints_optimizer_hotfixes/005-Query-Optimizer-Hotfixes.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/query-tuning-with-hints-optimizer-hotfixes 7 | 8 | *****************************************************************************/ 9 | 10 | --This is here for rerunnability, in case you cancel in the middle of a transaction 11 | IF @@TRANCOUNT > 0 12 | ROLLBACK; 13 | GO 14 | SET NOCOUNT ON; 15 | GO 16 | 17 | USE master; 18 | GO 19 | 20 | --Let's create a new database for this test 21 | IF DB_ID('QueryOptimizerHotfixes') IS NOT NULL 22 | BEGIN 23 | ALTER DATABASE QueryOptimizerHotfixes SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 24 | DROP DATABASE QueryOptimizerHotfixes; 25 | END 26 | 27 | CREATE DATABASE QueryOptimizerHotfixes 28 | GO 29 | 30 | USE QueryOptimizerHotfixes 31 | GO 32 | 33 | --We're going to repro a bug. The fix for this bug requires enabling Query Optimizer Hotfixes. 34 | --https://support.microsoft.com/en-us/help/3198775/fix-an-inefficient-query-plan-is-used-for-a-query-requiring-order-by-partitioning-column-of-a-table-with-single-partition 35 | 36 | --The loneliest partition function 37 | CREATE PARTITION FUNCTION pf (DATE) 38 | AS RANGE RIGHT 39 | FOR VALUES ( ); 40 | GO 41 | 42 | CREATE PARTITION SCHEME ps 43 | AS PARTITION pf 44 | ALL TO ([PRIMARY]); 45 | GO 46 | 47 | CREATE TABLE dbo.LetsTalkAboutQueryOptimizerHotfixes ( 48 | CXCol BIGINT IDENTITY NOT NULL, 49 | PartitioningCol DATE NOT NULL, 50 | CharCol CHAR(100) NOT NULL DEFAULT ('FOO'), 51 | IntCol INT NOT NULL DEFAULT (2) 52 | ) ON ps (PartitioningCol) 53 | GO 54 | 55 | /* Insert 1 million rows */ 56 | BEGIN TRAN 57 | DECLARE @i int = 0; 58 | WHILE @i < 1000000 59 | BEGIN 60 | INSERT dbo.LetsTalkAboutQueryOptimizerHotfixes (PartitioningCol) 61 | SELECT DATEADD(dd,@i,'2017-01-01') 62 | 63 | SET @i=@i+1; 64 | END 65 | COMMIT 66 | GO 67 | 68 | /* Now let's index our table */ 69 | CREATE UNIQUE CLUSTERED INDEX cx_LetsTalkAboutQueryOptimizerHotfixes 70 | on dbo.LetsTalkAboutQueryOptimizerHotfixes (CXCol, PartitioningCol); 71 | GO 72 | 73 | CREATE NONCLUSTERED INDEX ix_LetsTalkAboutQueryOptimizerHotfixes_PartitioningCol_CharCol on 74 | dbo.LetsTalkAboutQueryOptimizerHotfixes (PartitioningCol, CharCol); 75 | GO 76 | 77 | 78 | /* We're starting at compat level 130 (latest and greatest), with optimizer hotfixes OFF */ 79 | ALTER DATABASE [QueryOptimizerHotfixes] SET COMPATIBILITY_LEVEL = 130 80 | GO 81 | ALTER DATABASE SCOPED CONFIGURATION SET QUERY_OPTIMIZER_HOTFIXES = OFF; 82 | GO 83 | 84 | USE QueryOptimizerHotfixes; 85 | GO 86 | 87 | /* Now we need a low permission account for testing */ 88 | 89 | IF (SELECT COUNT(*) from sys.sql_logins where name='lowpermissionuser') = 0 90 | CREATE LOGIN lowpermissionuser with password='Password23'; 91 | GO 92 | 93 | CREATE USER lowpermissionuser for login [lowpermissionuser]; 94 | GO 95 | 96 | GRANT SELECT on OBJECT::dbo.LetsTalkAboutQueryOptimizerHotfixes TO [lowpermissionuser]; 97 | GO 98 | 99 | GRANT SHOWPLAN TO [lowpermissionuser]; 100 | GO 101 | 102 | EXECUTE AS USER = 'lowpermissionuser'; 103 | GO 104 | 105 | 106 | /* Let's repro that bug. 107 | We have an index with keys PartitioningCol, CharCol 108 | Look at the actual execution plan. 109 | If you see a sort operator, we're seeing the bug. 110 | 111 | Note: I'm using RECOMPILE hints ONLY to make it obvious that I'm 112 | not getting a behavior because of plan re-use anywhere here. 113 | */ 114 | SELECT IntCol 115 | FROM dbo.LetsTalkAboutQueryOptimizerHotfixes 116 | WHERE PartitioningCol < '2017-10-02' 117 | ORDER BY PartitioningCol DESC, CharCol DESC 118 | OPTION (RECOMPILE); 119 | GO 120 | 121 | SELECT IntCol 122 | FROM dbo.LetsTalkAboutQueryOptimizerHotfixes 123 | WHERE PartitioningCol < '2017-10-02' 124 | ORDER BY PartitioningCol DESC, CharCol DESC 125 | OPTION (RECOMPILE, QUERYTRACEON 4199); 126 | GO 127 | 128 | REVERT 129 | 130 | CREATE PROCEDURE dbo.Workaround 131 | AS 132 | SELECT IntCol 133 | FROM dbo.LetsTalkAboutQueryOptimizerHotfixes 134 | WHERE PartitioningCol < '2017-10-02' 135 | ORDER BY PartitioningCol DESC, CharCol DESC 136 | OPTION (RECOMPILE, QUERYTRACEON 4199); 137 | GO 138 | 139 | GRANT EXECUTE ON OBJECT::dbo.Workaround TO [lowpermissionuser]; 140 | GO 141 | 142 | EXECUTE AS USER = 'lowpermissionuser'; 143 | GO 144 | 145 | /* look at the plan... see the sort? */ 146 | exec dbo.Workaround; 147 | GO 148 | 149 | /* Check out 'Trace Flags' on properties of SELECT operator */ 150 | 151 | /* New syntax in 2016 SP1+ works for low permission users */ 152 | SELECT IntCol 153 | FROM dbo.LetsTalkAboutQueryOptimizerHotfixes 154 | WHERE PartitioningCol < '2017-10-02' 155 | ORDER BY PartitioningCol DESC, CharCol DESC 156 | OPTION (RECOMPILE, USE HINT ('ENABLE_QUERY_OPTIMIZER_HOTFIXES') ); 157 | GO 158 | 159 | REVERT; 160 | GO 161 | 162 | /* As of 2016 we can now 'bully' optimizer hotfixes at the DB level, 163 | more granular than global trace flag */ 164 | ALTER DATABASE SCOPED CONFIGURATION SET QUERY_OPTIMIZER_HOTFIXES = ON; 165 | GO 166 | 167 | EXECUTE AS USER = 'lowpermissionuser'; 168 | GO 169 | 170 | SELECT IntCol 171 | FROM dbo.LetsTalkAboutQueryOptimizerHotfixes 172 | WHERE PartitioningCol < '2017-10-02' 173 | ORDER BY PartitioningCol DESC, CharCol DESC 174 | OPTION (RECOMPILE); 175 | GO 176 | 177 | /* What if I have OPTIMIZER HOTFIXES on at the DB level, and I'm working on a query. 178 | And I want to know what plan it would have WITHOUT optimizer hotfixes on? 179 | There's not hint to turn OFF optimizer hotfixes. 180 | But you can do this... */ 181 | USE tempdb; 182 | GO 183 | 184 | SELECT IntCol 185 | FROM QueryOptimizerHotfixes.dbo.LetsTalkAboutQueryOptimizerHotfixes 186 | WHERE PartitioningCol < '2017-10-02' 187 | ORDER BY PartitioningCol DESC, CharCol DESC 188 | OPTION (RECOMPILE); 189 | GO 190 | 191 | -------------------------------------------------------------------------------- /query_writing_most_unique_names/Most-Unique-Names_00-Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/a-query-writing-sqlchallenge-the-most-unique-names/ 7 | 8 | Setup: 9 | Download BabbyNames.bak.zip (43 MB database backup) 10 | https://github.com/LitKnd/BabbyNames/releases/tag/v1.3 11 | Then review and run the script below on a SQL Server dedicated test instance 12 | Developer Edition recommended (Enteprise and Evaluation Editions will work too) 13 | 14 | *****************************************************************************/ 15 | 16 | 17 | SET NOCOUNT, ANSI_NULLS, QUOTED_IDENTIFIER ON 18 | GO 19 | USE master; 20 | GO 21 | 22 | IF DB_ID('BabbyNames') IS NOT NULL 23 | BEGIN 24 | ALTER DATABASE BabbyNames 25 | SET SINGLE_USER 26 | WITH ROLLBACK IMMEDIATE; 27 | END 28 | GO 29 | 30 | RESTORE DATABASE BabbyNames 31 | FROM DISK=N'S:\MSSQL\Backup\BabbyNames.bak' 32 | WITH 33 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames.mdf', 34 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames_log.ldf', 35 | REPLACE, 36 | RECOVERY; 37 | GO 38 | -------------------------------------------------------------------------------- /query_writing_most_unique_names/Most-Unique-Names_01-Challenge.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/a-query-writing-sqlchallenge-the-most-unique-names/ 7 | 8 | CHALLENGE FILE 9 | 10 | *****************************************************************************/ 11 | 12 | USE BabbyNames; 13 | GO 14 | 15 | 16 | 17 | 18 | /***************************************************************************** 19 | CHALLENGE 1 20 | 21 | Write a query that returns 22 | The top 3 rows based upon 23 | The LOWEST "AvgUsePerName" for a given StateCode/ReportYear combo 24 | 25 | Use only the agg.FirstNameByYearState table 26 | 27 | Return the columns: 28 | StateCode 29 | ReportYear 30 | UniqueNames: the number of distinct names reported for that StateCode and ReportYear 31 | TotalNamed: the total number of babies reported named that for that StateCode and ReportYear 32 | AvgUsePerName: calculate as UniqueNames / TotalNamed 33 | Express result as NUMERIC (10,1) 34 | 35 | Order the results from LOWEST AvgUsePerNames to HIGHEST 36 | 37 | Results should look like: 38 | StateCode ReportYear UniqueNames TotalNamed AvgUsePerName 39 | ---------------------------------------------------------------- 40 | NV 1911 13 85 6.5 41 | NV 1910 10 67 6.7 42 | AK 1912 20 141 7.1 43 | 44 | *****************************************************************************/ 45 | 46 | 47 | 48 | 49 | 50 | 51 | 52 | 53 | 54 | 55 | 56 | GO 57 | 58 | 59 | 60 | 61 | /***************************************************************************** 62 | CHALLENGE 2 63 | (This is similar to Challenge 1, but we don't care about ReportYear this time) 64 | 65 | Write a query that returns 66 | The top 3 rows based upon 67 | The LOWEST "AvgUsePerName" for a given StateCode 68 | 69 | Use only the agg.FirstNameByYearState table 70 | 71 | Return the columns: 72 | StateCode 73 | UniqueNames: the number of distinct names reported for that StateCode over all years 74 | TotalNamed: the total number of babies reported named that for that StateCode over all years 75 | AvgUsePerName: calculate as UniqueNames / TotalNamed 76 | Express result as NUMERIC (10,1) 77 | 78 | Order the results from LOWEST AvgUsePerNames to HIGHEST 79 | 80 | Results should look like: 81 | StateCode UniqueNames TotalNamed AvgUsePerName 82 | AK 1620 430161 265.5 83 | WY 1559 435016 279.0 84 | NV 2976 940408 316.0 85 | 86 | *****************************************************************************/ 87 | 88 | 89 | 90 | 91 | 92 | 93 | 94 | 95 | 96 | 97 | 98 | GO 99 | 100 | 101 | 102 | /***************************************************************************** 103 | CHALLENGE 3 104 | (This builds on Challenge 2) 105 | 106 | Write a query that returns 107 | For the ONE state with the LOWEST value for AvgUserPerName over ALL years 108 | One row for every name used in that state with the detail defined below 109 | 110 | Use the agg.FirstNameByYearState table and ref.FirstName tables 111 | 112 | Return the columns: 113 | StateCode: the StateCode who is detailed in the results 114 | TotalNamed: the total number of babies reported named that for that StateCode over all years 115 | FirstName 116 | 117 | Order the results from 118 | Lowest TotalNamed to highest 119 | Then alphabetically by FirstName from A to Z 120 | 121 | 122 | Results should return 1620 rows total 123 | The first three rows of the 1620 should look like: 124 | 125 | StateCode TotalNamed FirstName 126 | AK 5 Ace 127 | AK 5 Ada 128 | AK 5 Addyson 129 | *****************************************************************************/ 130 | 131 | 132 | 133 | 134 | 135 | 136 | 137 | 138 | 139 | 140 | 141 | GO 142 | 143 | 144 | /***************************************************************************** 145 | CHALLENGE 4 146 | (This is similar to Challenge 3, but instead of returning rows for the TOP 1 state, now 147 | you need to write a procedure that lets the user specified the desired dense_rank as a parameter) 148 | 149 | Write a stored procedure named dbo.ChallengeFour 150 | Which takes a parameter, @denserank, a TINYINT 151 | 152 | dbo.ChallengeFour calculates DENSE_RANK for each state 153 | Based on AvgUserPerName over ALL years for that state 154 | Lowest AvgUsePerName for a state has rank 1 155 | Next lowest has rank 2, etc 156 | Return one row for every name used in that state with the detail defined below 157 | DENSE_RANK documentation: https://docs.microsoft.com/en-us/sql/t-sql/functions/dense-rank-transact-sql 158 | 159 | Use the agg.FirstNameByYearState table and ref.FirstName tables 160 | 161 | Return the columns: 162 | StateCode: the StateCode who is detailed in the results 163 | TotalNamed: the total number of babies reported named that for that StateCode over all years 164 | FirstName 165 | 166 | Order the results from 167 | Lowest TotalNamed to highest 168 | Then alphabetically by FirstName from A to Z 169 | 170 | 171 | When executed with... 172 | EXEC dbo.ChallengeFour @denserank = 2; 173 | 174 | Results should return 1559 rows total 175 | The first three rows of the 1559 rows should look like: 176 | 177 | StateCode TotalNamed FirstName 178 | WY 5 Abigale 179 | WY 5 Abigayle 180 | WY 5 Abraham 181 | 182 | *****************************************************************************/ 183 | 184 | CREATE OR ALTER PROCEDURE dbo.ChallengeFour @denserank TINYINT 185 | AS 186 | BEGIN; 187 | 188 | 189 | 190 | /* Fill in code here */ 191 | 192 | 193 | 194 | 195 | 196 | 197 | END; 198 | GO 199 | 200 | --Command for testing 201 | EXEC dbo.ChallengeFour @denserank = 2; 202 | GO 203 | -------------------------------------------------------------------------------- /query_writing_peak_year/PeakYear_00_Restore-Database.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/tune-the-peak-years-procedure-sqlchallenge/ 7 | 8 | 🛑 Caution: This script restores of databases and changes system config! 🛑 9 | ☢️ Suitable for dedicated test instances only ☢️ 10 | 11 | This restores the BabbyNames database, download it from: 12 | https://drive.google.com/file/d/1w0ZGZKHq4N7n6eyP5puu63MuSH3o_hWb/view?usp=sharing 13 | 14 | *The database will restore to SQL Server 2017 and higher only* 15 | 16 | Read through this script and make sure you want to use these settings 17 | You will also likely need to change drive / path information on the restore command 18 | 19 | *****************************************************************************/ 20 | 21 | 22 | use master; 23 | GO 24 | 25 | exec sp_configure 'show advanced options', 1; 26 | GO 27 | RECONFIGURE 28 | GO 29 | 30 | 31 | exec sp_configure 'cost threshold for parallelism', 50; 32 | exec sp_configure 'max degree of parallelism', 4; 33 | exec sp_configure 'max server memory (MB)', 4000; 34 | GO 35 | 36 | RECONFIGURE 37 | GO 38 | 39 | 40 | IF DB_ID('BabbyNames') IS NOT NULL 41 | BEGIN 42 | ALTER DATABASE BabbyNames SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 43 | END 44 | GO 45 | 46 | /* Change drive / folder information as needed */ 47 | RESTORE DATABASE BabbyNames FROM 48 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_1_of_4.bak', 49 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_2_of_4.bak', 50 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_3_of_4.bak', 51 | DISK = N'S:\MSSQL\Backup\BabbyNames2017_QTJS_4_of_4.bak' 52 | WITH REPLACE; 53 | GO 54 | -------------------------------------------------------------------------------- /query_writing_peak_year/PeakYear_01_Challenge.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/tune-the-peak-years-procedure-sqlchallenge/ 7 | 8 | 9 | CHALLENGE FILE: ⛰ Peak Year 10 | *****************************************************************************/ 11 | 12 | 13 | USE BabbyNames; 14 | GO 15 | 16 | --Create these indexes and constraint 17 | --This took 2.5 minutes on my test instance 18 | 19 | CREATE INDEX ix_FirstNameByBirthDate_2002_2017_FirstNameId 20 | on dbo.FirstNameByBirthDate_2002_2017 (FirstNameId); 21 | GO 22 | CREATE INDEX ix_FirstNameByBirthDate_2002_2017_Gender_FirstNameId 23 | on dbo.FirstNameByBirthDate_2002_2017 (Gender, FirstNameId); 24 | GO 25 | ALTER TABLE dbo.FirstNameByBirthDate_2002_2017 WITH CHECK 26 | ADD CONSTRAINT ck_FirstNameByBirthDate_2002_2017_Gender 27 | CHECK (Gender In ('M','F')); 28 | GO 29 | 30 | --Create this procedure (super fast) 31 | CREATE OR ALTER PROC dbo.PeakYear 32 | @FirstName1 VARCHAR(255), 33 | @FirstName2 VARCHAR(255), 34 | @FirstName3 VARCHAR(255) 35 | AS 36 | 37 | WITH mycount AS ( 38 | SELECT 39 | fn.FirstName, 40 | fnbd.Gender, 41 | fnbd.BirthYear, 42 | COUNT_BIG(*) as NumberBorn 43 | FROM dbo.FirstNameByBirthDate_2002_2017 as fnbd 44 | JOIN ref.FirstName as fn on 45 | fn.FirstNameId = fnbd.FirstNameId 46 | WHERE 47 | fn.FirstName = @FirstName1 or 48 | fn.FirstName = @FirstName2 or 49 | fn.FirstName = @FirstName3 50 | GROUP BY 51 | fn.FirstName, 52 | fnbd.Gender, 53 | fnbd.BirthYear 54 | ), yearrank AS ( 55 | SELECT 56 | FirstName, 57 | Gender, 58 | BirthYear as PeakYear, 59 | NumberBorn, 60 | RANK () OVER ( partition by FirstName, Gender ORDER BY NumberBorn desc ) as YearRanked 61 | FROM mycount 62 | ) 63 | SELECT FirstName, Gender, PeakYear, NumberBorn 64 | FROM yearrank 65 | WHERE YearRanked = 1 66 | ORDER BY FirstName, Gender; 67 | GO 68 | 69 | 70 | /***************************************************************************** 71 | ✨ CHALLENGE ✨ 72 | 73 | Improve the performance of this query by changing the TSQL only 74 | 75 | * Do not change indexes 76 | * Measure the performance using the two sample execution statements below 77 | 78 | *****************************************************************************/ 79 | SET STATISTICS IO, TIME ON; 80 | GO 81 | 82 | EXEC dbo.PeakYear 'John', 'Jacob', 'Mary' WITH RECOMPILE; 83 | GO 84 | /* 85 | CPU time = 2656 ms, elapsed time = 2655 ms. 86 | */ 87 | 88 | 89 | EXEC dbo.PeakYear 'Kendra', 'Mister', 'Stormy' WITH RECOMPILE; 90 | GO 91 | 92 | /* 93 | CPU time = 156 ms, elapsed time = 173 ms. 94 | */ -------------------------------------------------------------------------------- /rcsi_and_snapshot_isolation/RCSI-and-Snapshot-Isolation.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/course/read-committed-snapshot-and-snapshot-isolation/ 7 | 8 | Setup: 9 | Download BabbyNames.bak.zip (41 MB database backup) 10 | https://github.com/LitKnd/BabbyNames/releases/tag/v1.2 11 | 12 | Then review and run the script below on a SQL Server 2016 dedicated test instance 13 | Developer Edition recommended (Enteprise and Evaluation Editions will work too) 14 | 15 | *****************************************************************************/ 16 | 17 | /* Doorstop */ 18 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 19 | GO 20 | 21 | 22 | /**************************************************** 23 | Restore database 24 | ****************************************************/ 25 | SET NOCOUNT ON; 26 | GO 27 | USE master; 28 | GO 29 | 30 | IF DB_ID('BabbyNames') IS NOT NULL 31 | BEGIN 32 | ALTER DATABASE BabbyNames 33 | SET SINGLE_USER 34 | WITH ROLLBACK IMMEDIATE; 35 | END 36 | GO 37 | 38 | RESTORE DATABASE BabbyNames 39 | FROM DISK=N'S:\MSSQL\Backup\BabbyNames.bak' 40 | WITH 41 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames.mdf', 42 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames_log.ldf', 43 | REPLACE, 44 | RECOVERY; 45 | GO 46 | 47 | 48 | /**************************************************** 49 | Read committed lets us read rows twice, or miss rows entirely. 50 | Snapshot isolation to the rescue! 51 | ****************************************************/ 52 | USE BabbyNames; 53 | GO 54 | 55 | 56 | SELECT name, 57 | is_read_committed_snapshot_on, 58 | snapshot_isolation_state_desc 59 | FROM sys.databases 60 | WHERE DB_ID() = database_id; 61 | GO 62 | 63 | 64 | /* As soon as this is 'ON', versioning will begin - 65 | even if nothing is using it */ 66 | ALTER DATABASE BabbyNames SET ALLOW_SNAPSHOT_ISOLATION ON; 67 | GO 68 | 69 | SELECT name, 70 | is_read_committed_snapshot_on, 71 | snapshot_isolation_state_desc 72 | FROM sys.databases 73 | WHERE DB_ID() = database_id; 74 | GO 75 | 76 | CREATE INDEX ix_FirstName_FirstName on ref.FirstName (FirstName); 77 | GO 78 | 79 | 80 | --We have 95,025 names 81 | --We're going to move the first name, 'Aaban', to the end of the index 82 | --by updating it to 'ZZZaaban' and back repeatedly. 83 | SELECT FirstName 84 | FROM ref.FirstName; 85 | GO 86 | 87 | --Look at the plan for this query. It's using just the NC index on FirstName 88 | SELECT COUNT(*) AS NameCount 89 | FROM ref.FirstName; 90 | GO 91 | 92 | /* Uncomment and run this in another session ... */ 93 | --USE BabbyNames; 94 | --GO 95 | --SET NOCOUNT ON; 96 | --GO 97 | --UPDATE ref.FirstName SET FirstName='ZZZaaban' WHERE FirstName='Aaban'; 98 | 99 | --UPDATE ref.FirstName SET FirstName='Aaban' WHERE FirstName='ZZZaaban'; 100 | 101 | --GO 100000 102 | 103 | 104 | /* Now count the names 2K times. This takes ~10 seconds */ 105 | /* Make sure actual plans are off :) */ 106 | /* We have enabled snapshot isolation for the database, but we aren't using it... 107 | we are in plain old Read Committed here */ 108 | DROP TABLE IF EXISTS dbo.NameCount; 109 | GO 110 | CREATE TABLE dbo.NameCount ( NameCount int); 111 | GO 112 | 113 | DECLARE @i int = 1 114 | WHILE @i <= 2000 115 | BEGIN 116 | INSERT dbo.NameCount (NameCount) 117 | SELECT COUNT(*) AS NameCount 118 | FROM ref.FirstName; 119 | 120 | SET @i = @i + 1; 121 | END 122 | GO 123 | 124 | /* How many names did we count? 125 | Reminder: there were ALWAYS the same amount of names, we were just updating the name value*/ 126 | SELECT NameCount, 127 | COUNT(*) as NumberCounted 128 | FROM dbo.NameCount 129 | GROUP BY NameCount 130 | ORDER BY 1; 131 | GO 132 | 133 | 134 | /* Now do the same reads but under SNAPSHOT */ 135 | SET TRANSACTION ISOLATION LEVEL SNAPSHOT; 136 | GO 137 | 138 | DROP TABLE IF EXISTS dbo.NameCount; 139 | GO 140 | CREATE TABLE dbo.NameCount ( NameCount int); 141 | GO 142 | 143 | DECLARE @i int = 1 144 | WHILE @i <= 2000 145 | BEGIN 146 | INSERT dbo.NameCount (NameCount) 147 | SELECT COUNT(*) AS NameCount 148 | FROM ref.FirstName; 149 | 150 | SET @i = @i + 1; 151 | END 152 | GO 153 | 154 | SELECT NameCount, 155 | COUNT(*) as NumberCounted 156 | FROM dbo.NameCount 157 | GROUP BY NameCount 158 | ORDER BY 1; 159 | GO 160 | 161 | 162 | /* Reset isolation level */ 163 | SET TRANSACTION ISOLATION LEVEL READ COMMITTED; 164 | GO 165 | /* Stop the updates */ 166 | 167 | -------------------------------------------------------------------------------- /read_committed_is_bonkers/Read-Committed-is-Bonkers.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course: https://littlekendra.com/?post_type=course&p=66294 7 | 8 | Setup: 9 | Download BabbyNames.bak.zip (43 MB database backup) 10 | https://github.com/LitKnd/BabbyNames/releases/tag/v1.1 11 | 12 | Then review and run the script below on a SQL Server 2016 dedicated test instance 13 | Developer Edition recommended (Enteprise and Evaluation Editions will work too) 14 | 15 | *****************************************************************************/ 16 | 17 | /* Doorstop */ 18 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 19 | GO 20 | 21 | 22 | /**************************************************** 23 | Restore database 24 | ****************************************************/ 25 | SET NOCOUNT ON; 26 | GO 27 | USE master; 28 | GO 29 | 30 | IF DB_ID('BabbyNames') IS NOT NULL 31 | BEGIN 32 | ALTER DATABASE BabbyNames 33 | SET SINGLE_USER 34 | WITH ROLLBACK IMMEDIATE; 35 | END 36 | GO 37 | 38 | RESTORE DATABASE BabbyNames 39 | FROM DISK=N'S:\MSSQL\Backup\BabbyNames.bak' 40 | WITH 41 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames.mdf', 42 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames_log.ldf', 43 | REPLACE, 44 | RECOVERY; 45 | GO 46 | 47 | USE BabbyNames; 48 | GO 49 | 50 | /**************************************************** 51 | Read committed lets us read rows twice, or miss rows entirely 52 | ****************************************************/ 53 | 54 | /* Pages and rows in the clustered index */ 55 | SELECT index_type_desc, 56 | alloc_unit_type_desc, 57 | index_level, 58 | page_count, 59 | record_count 60 | FROM sys.dm_db_index_physical_stats 61 | (DB_ID(),OBJECT_ID('ref.FirstName'), 1, NULL, 'detailed') 62 | ORDER BY 1, 2, 3 DESC; 63 | GO 64 | 65 | CREATE INDEX ix_FirstName_FirstName on ref.FirstName (FirstName); 66 | GO 67 | 68 | 69 | /* Pages and rows in this non-clustered index */ 70 | SELECT index_type_desc, 71 | alloc_unit_type_desc, 72 | index_level, 73 | page_count, 74 | record_count 75 | FROM sys.dm_db_index_physical_stats 76 | (DB_ID(), 77 | OBJECT_ID('ref.FirstName'), 78 | (select index_id from sys.indexes where object_id=OBJECT_ID('ref.FirstName') and name = 'ix_FirstName_FirstName'), 79 | NULL, 80 | 'detailed') 81 | ORDER BY 1, 2, 3 DESC; 82 | GO 83 | 84 | 85 | --How many names do we have? 86 | --We're going to move the first name, 'Aaban', to the end of the index 87 | --by updating it to 'ZZZaaban' and back repeatedly. 88 | SELECT FirstName 89 | FROM ref.FirstName; 90 | GO 91 | 92 | --Look at the plan for this query. It's using just the NC index on FirstName 93 | SELECT COUNT(*) AS NameCount 94 | FROM ref.FirstName; 95 | GO 96 | 97 | /* Which page has the row before we change the name? */ 98 | SELECT 99 | sys.fn_PhysLocFormatter (%%physloc%%) as [File:Page:Slot], 100 | FirstName 101 | FROM ref.FirstName WITH (INDEX(ix_FirstName_FirstName)) 102 | WHERE FirstName in ('Aaban', 'ZZZaaban') 103 | GO 104 | 105 | --File:Page:Slot FirstName 106 | --(1:9864:0) Aaban 107 | 108 | 109 | /* Update the row */ 110 | UPDATE ref.FirstName SET FirstName='ZZZaaban' WHERE FirstName='Aaban'; 111 | GO 112 | 113 | /* Which page has the row now? */ 114 | SELECT 115 | sys.fn_PhysLocFormatter (%%physloc%%) as [File:Page:Slot], 116 | FirstName 117 | FROM ref.FirstName WITH (INDEX(ix_FirstName_FirstName)) 118 | WHERE FirstName in ('Aaban', 'ZZZaaban') 119 | GO 120 | 121 | --File:Page:Slot FirstName 122 | --(1:10115:12) ZZZaaban 123 | 124 | 125 | /* Update the row again */ 126 | UPDATE ref.FirstName SET FirstName='Aaban' WHERE FirstName='ZZZaaban'; 127 | GO 128 | 129 | 130 | /* Which page has the row now? */ 131 | SELECT 132 | sys.fn_PhysLocFormatter (%%physloc%%) as [File:Page:Slot], 133 | FirstName 134 | FROM ref.FirstName WITH (INDEX(ix_FirstName_FirstName)) 135 | WHERE FirstName in ('Aaban', 'ZZZaaban') 136 | GO 137 | 138 | 139 | /* Uncomment and run this in another session ... */ 140 | --USE BabbyNames; 141 | --GO 142 | --SET NOCOUNT ON; 143 | --GO 144 | --UPDATE ref.FirstName SET FirstName='ZZZaaban' WHERE FirstName='Aaban'; 145 | 146 | --UPDATE ref.FirstName SET FirstName='Aaban' WHERE FirstName='ZZZaaban'; 147 | 148 | --GO 100000 149 | 150 | 151 | /* Now count the names 10K times. This takes around a minute */ 152 | /* Make sure actual plans are off :) */ 153 | DROP TABLE IF EXISTS dbo.NameCount; 154 | GO 155 | CREATE TABLE dbo.NameCount ( NameCount int); 156 | GO 157 | 158 | DECLARE @i int = 1 159 | WHILE @i <= 10000 160 | BEGIN 161 | INSERT dbo.NameCount (NameCount) 162 | SELECT COUNT(*) AS NameCount 163 | FROM ref.FirstName; 164 | 165 | SET @i = @i + 1; 166 | END 167 | GO 168 | 169 | 170 | /* How many names did we count? 171 | Reminder: there were ALWAYS the same amount names, we were just updating the name value*/ 172 | SELECT NameCount, 173 | COUNT(*) as NumberCounted 174 | FROM dbo.NameCount 175 | GROUP BY NameCount 176 | ORDER BY 1; 177 | GO 178 | 179 | 180 | /* 181 | Stop the updates in the other session, 182 | Head back to the slides 183 | */ 184 | 185 | -------------------------------------------------------------------------------- /speed_up_popular_names_sqlchallenge/Speed-Up-This-Query_Popular-Names_01_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/sqlchallenge-speed-up-the-popular-names-query/ 7 | 8 | This SQLChallenge uses the free BabbyNames sample database 9 | Download BabbyNames.bak.zip (43 MB database backup) 10 | https://github.com/LitKnd/BabbyNames/releases/tag/v1.2 11 | 12 | *****************************************************************************/ 13 | 14 | RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 15 | GO 16 | 17 | /**************************************************** 18 | Restore database 19 | ****************************************************/ 20 | SET NOCOUNT ON; 21 | GO 22 | USE master; 23 | GO 24 | 25 | IF DB_ID('BabbyNames') IS NOT NULL 26 | BEGIN 27 | ALTER DATABASE BabbyNames 28 | SET SINGLE_USER 29 | WITH ROLLBACK IMMEDIATE; 30 | END 31 | GO 32 | 33 | RESTORE DATABASE BabbyNames 34 | FROM DISK=N'S:\MSSQL\Backup\BabbyNames.bak' 35 | WITH 36 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames.mdf', 37 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames_log.ldf', 38 | REPLACE, 39 | RECOVERY; 40 | GO 41 | 42 | USE BabbyNames; 43 | GO 44 | 45 | 46 | ALTER DATABASE BabbyNames SET COMPATIBILITY_LEVEL = 140; 47 | GO 48 | 49 | /***************************************************************************** 50 | CHALLENGE: SPEED UP THE "POPULAR NAMES" QUERY 51 | 52 | Rewrite the TSQL so the query uses less than 500 logical reads when run for 1991 53 | Do not add/change any indexes, change only the TSQL 54 | The query should produce the exact same result set after the rewrite 55 | *****************************************************************************/ 56 | 57 | SET STATISTICS TIME, IO ON 58 | GO 59 | 60 | DECLARE @YearToRank INT = 1991; 61 | 62 | with rankbyyear AS ( 63 | SELECT fnby.ReportYear, 64 | DENSE_RANK() OVER (PARTITION BY ReportYear ORDER BY NameCount DESC ) as RankThatYear, 65 | FirstNameId, 66 | Gender 67 | FROM agg.FirstNameByYear fnby 68 | ) 69 | SELECT 70 | fn.FirstName, 71 | startyear.Gender, 72 | twenty_years_prior.RankThatYear as [Rank 20 years prior], 73 | ten_years_prior.RankThatYear as [Rank 10 years prior], 74 | startyear.RankThatYear as [Rank], 75 | ten_years_later.RankThatYear as [Rank 10 years later], 76 | twenty_years_later.RankThatYear as [Rank 20 years later] 77 | FROM rankbyyear AS startyear 78 | JOIN rankbyyear AS ten_years_later on 79 | startyear.ReportYear + 10 = ten_years_later.ReportYear 80 | and startyear.FirstNameId = ten_years_later.FirstNameId 81 | and startyear.Gender = ten_years_later.Gender 82 | LEFT JOIN rankbyyear AS ten_years_prior on 83 | startyear.ReportYear - 10 = ten_years_prior.ReportYear 84 | and startyear.FirstNameId = ten_years_prior.FirstNameId 85 | and startyear.Gender = ten_years_prior.Gender 86 | LEFT JOIN rankbyyear AS twenty_years_prior on 87 | startyear.ReportYear - 20 = twenty_years_prior.ReportYear 88 | and startyear.FirstNameId = twenty_years_prior.FirstNameId 89 | and startyear.Gender = twenty_years_prior.Gender 90 | LEFT JOIN rankbyyear AS twenty_years_later on 91 | startyear.ReportYear + 20 = twenty_years_later.ReportYear 92 | and startyear.FirstNameId = twenty_years_later.FirstNameId 93 | and startyear.Gender = twenty_years_later.Gender 94 | JOIN ref.FirstName fn on startyear.FirstNameId=fn.FirstNameId 95 | WHERE 96 | startyear.ReportYear = @YearToRank 97 | and startyear.RankThatYear <= 10 98 | ORDER BY startyear.RankThatYear, startyear.Gender; 99 | GO 100 | 101 | SET STATISTICS TIME, IO OFF 102 | GO 103 | 104 | 105 | --Table 'FirstNameByYear'. Scan count 25, logical reads 26010, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. 106 | --Table 'Worktable'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. 107 | --Table 'Workfile'. Scan count 0, logical reads 0, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. 108 | --Table 'FirstName'. Scan count 5, logical reads 1414, physical reads 0, read-ahead reads 0, lob logical reads 0, lob physical reads 0, lob read-ahead reads 0. 109 | 110 | -- SQL Server Execution Times: 111 | -- CPU time = 13064 ms, elapsed time = 4596 ms. -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/00-Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/ssms-shortcuts-secrets/ 7 | 8 | Do these quick pre-requisites: 9 | 1) Download WideWorldImporters-Full.bak (database backup) 10 | Restore it to a SQL Server 2016 test instance (restore script below) 11 | https://github.com/Microsoft/sql-server-samples/releases/tag/wide-world-importers-v1.0 12 | 13 | 2) Install sp_WhoIsActive from http://whoisactive.com/ 14 | 15 | 3) Make sure you have the latest copy of SQL Server Management Studio 16 | https://docs.microsoft.com/en-us/sql/ssms/download-sql-server-management-studio-ssms 17 | 18 | This is worth doing so you can step through the demos yourself! 19 | 20 | *****************************************************************************/ 21 | 22 | 23 | USE master; 24 | GO 25 | 26 | IF DB_ID('WideWorldImporters') IS NOT NULL 27 | ALTER DATABASE WideWorldImporters SET OFFLINE WITH ROLLBACK IMMEDIATE 28 | 29 | /* EDIT DRIVE/FOLDER LOCATIONS AS NEEDED */ 30 | RESTORE DATABASE WideWorldImporters FROM DISK= 31 | 'S:\MSSQL\Backup\WideWorldImporters-Full.bak' 32 | WITH REPLACE, 33 | MOVE 'WWI_Primary' to 'S:\MSSQL\Data\WideWorldImporters.mdf', 34 | MOVE 'WWI_UserData' to 'S:\MSSQL\Data\WideWorldImporters_UserData.ndf', 35 | MOVE 'WWI_Log' to 'S:\MSSQL\Data\WideWorldImporters.ldf', 36 | MOVE 'WWI_InMemory_Data_1' to 'S:\MSSQL\Data\WideWorldImporters_InMemory_Data_1'; 37 | GO 38 | -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/03-Use-Object-Explorer-Details.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/ssms-shortcuts-secrets/ 7 | 8 | 9 | *****************************************************************************/ 10 | 11 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 12 | GO 13 | 14 | 15 | 16 | 17 | /***************************************************************************** 18 | Problem: I need to script out more than one index 19 | 20 | Solution: Script out multiple objects at the same time 21 | *****************************************************************************/ 22 | 23 | /* Demo: 24 | Try to script out all the indexes on Sales.Customers from Object Explorer. 25 | Be sad for a moment. 26 | 27 | Keep Object Explorer open! 28 | 29 | Object Explorer Details comes to your rescue 30 | Open by pressing F7, or using View -> Object Explorer Details (ALT V, Arrow down) 31 | Navigate to Sales.Customers 32 | You can now select a range of indexes using the SHIFT key 33 | CTRL + A selects ALL 34 | Script em all as create to a new window 35 | 36 | Click the 'Synchronize' button in Object Explorer Details 37 | Watch what happens in Object Explorer 38 | */ 39 | 40 | 41 | 42 | 43 | 44 | 45 | /***************************************************************************** 46 | Problem: I need to find every ___ named ____ 47 | 48 | Solution: Search for objects and view properties (maybe) 49 | 50 | I�m often hesitant to use this feature on production servers� I like it much more for dev servers and pre-production. 51 | 52 | If you have hundreds of databases, or high number of objects in each database, be careful! 53 | 54 | Think about it this way: when we use this search, we�re running a script where we can�t see the code. 55 | 56 | Stopping it may be tricky if it takes too long or SSMS freezes up (and we all know that happens sometimes) 57 | What if it gets blocked? 58 | 59 | So for production, I'd rather search in source control 60 | 61 | But for non-production environments... 62 | *****************************************************************************/ 63 | 64 | 65 | /* Demo: 66 | Open Object Explorer and Object Explorer Details 67 | 68 | Navigate to the WideWorldImporters database 69 | 70 | Search for: or% 71 | 72 | Search for: %a% 73 | 74 | Click a row 75 | Right Click 76 | Select Synchronize 77 | 78 | Use 'Back' 79 | */ -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/04-Work-With-Execution-Plans.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/ssms-shortcuts-secrets/ 7 | 8 | 9 | *****************************************************************************/ 10 | 11 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 12 | GO 13 | 14 | 15 | 16 | /***************************************************************************** 17 | Problem: What the heck is going on in my query? 18 | 19 | Solution: Display estimated and actual execution plans 20 | *****************************************************************************/ 21 | 22 | USE WideWorldImporters; 23 | GO 24 | 25 | 26 | /* Review: what parameters does this take? 27 | Hover with mouse 28 | OR -- put cursor anywhere on name, then CTRL + K, CTRL + I 29 | I remember this as "Control Komplete Info" 30 | */ 31 | EXEC [Integration].[GetSaleUpdates] 32 | GO 33 | /* Reminder ... another way to do this: 34 | Highlight the ENTIRE proc name (no spaces), 35 | then hit ALT+F1 (built-in shortcut for sp_help) 36 | */ 37 | 38 | 39 | 40 | /* 41 | Use CTRL + L to see an estimated execution plan. 42 | This does NOT execute the query 43 | Show the button that does the same thing. 44 | */ 45 | EXEC [Integration].[GetSaleUpdates] @LastCutoff = '2015-01-01', @NewCutoff = '2016-01-01' 46 | GO 47 | 48 | /* Use mouse to drag around the plan. 49 | Use CTRL + Scroll Bar to zoom */ 50 | 51 | 52 | /* 53 | Use CTRL + M to toggle 'Actual Execution Plans' 54 | Then execute the query (CTRL + E) 55 | */ 56 | EXEC [Integration].[GetSaleUpdates] @LastCutoff = '2015-01-01', @NewCutoff = '2016-01-01' 57 | GO 58 | 59 | 60 | /* F6 to toggle through results windows. 61 | New in SSMS 17.2: 62 | In the execution plan pane, hit: CTRL + F 63 | 64 | Select Table contains stock 65 | 66 | This will search the plan properties 67 | Arrow through to see which nodes in the plan it finds 68 | 69 | */ 70 | 71 | -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/05-Extended-Events.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/ssms-shortcuts-secrets/ 7 | 8 | 9 | *****************************************************************************/ 10 | 11 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 12 | GO 13 | 14 | 15 | 16 | /***************************************************************************** 17 | Problem: Which Extended Events Wizard should I use? 18 | 19 | Solution: Use the one which does NOT call itself a wizard. 20 | *****************************************************************************/ 21 | 22 | /* Demo: 23 | Go to Management -> Extended Events 24 | 25 | Right click on the Sessions folder 26 | 27 | There's "New Session Wizard" and "New Session" 28 | 29 | Both are wizards! 30 | 31 | Both are complicated 32 | 33 | But the "Wizard" doesn't let you do everything 34 | 35 | My advice: Just use "New Session" and get used to one wizard 36 | */ 37 | 38 | 39 | 40 | 41 | 42 | /***************************************************************************** 43 | Problem: I'm tired of setting a filter on each event 44 | 45 | Solution: Set multiple filters at once 46 | *****************************************************************************/ 47 | 48 | --Let's say we want to run a trace just for our session id 49 | SELECT @@SPID; 50 | GO 51 | 52 | /* Demo: 53 | 54 | Management - Extended Events 55 | Right click, new session 56 | 57 | Name it: Tuning 58 | Template: Tuning 59 | 60 | Events: Configure 61 | Select all the events using SHIFT 62 | Click on the 'Filter (Predicate)' tab 63 | 64 | Add a filter for sqlserver.session_id = your session number 65 | 66 | Go to data storage, use S:\XEvents\Tuning 67 | 68 | Start the trace 69 | */ 70 | 71 | ALTER EVENT SESSION [Tuning] ON SERVER STATE = START; 72 | GO 73 | 74 | 75 | /* Run a query and then review the output */ 76 | use WideWorldImporters 77 | GO 78 | SELECT 'CAN YOU SEE ME NOW????'; 79 | GO 80 | 81 | 82 | 83 | /* Stop and delete the trace */ 84 | ALTER EVENT SESSION [Tuning] ON SERVER STATE = STOP; 85 | GO 86 | 87 | DROP EVENT SESSION [Tuning] ON SERVER; 88 | GO 89 | 90 | 91 | 92 | 93 | 94 | /***************************************************************************** 95 | Problem: I can't find an event I read about in a blog post 96 | 97 | Solution: Check the (hidden) 'Debug' events 98 | *****************************************************************************/ 99 | 100 | /* Demo: I read a blog about the query_thread_profile event, 101 | and I want to test it on my demo instance. 102 | 103 | Management - Extended Events 104 | Right click, new session 105 | 106 | Name it: query_thread_profile 107 | Events: query_thread_profile 108 | 109 | Nothing shows up!?!?! 110 | 111 | Click the down carat to the right of 'Channel' 112 | Now you can add the event 113 | 114 | Go to data storage 115 | I have an error because of a bug in my version of SSMS 116 | (https://connect.microsoft.com/SQLServer/feedback/details/3133065) 117 | Paste in S:\XEvents\test 118 | 119 | Note: this particular event is VERY verbose. 120 | I just picked it as an example of a debug event :) 121 | Test carefully. 122 | */ 123 | 124 | 125 | 126 | /* Stop and delete the trace */ 127 | ALTER EVENT SESSION [query_thread_profile] ON SERVER STATE = STOP; 128 | GO 129 | 130 | DROP EVENT SESSION [query_thread_profile] ON SERVER; 131 | GO -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/06-SSMS-Diagnostics.sql: -------------------------------------------------------------------------------- 1 | 2 | 3 | -- NOTE: MICROSOFT NO LONGER SUPPORTS THIS EXTENSION 4 | -- THIS FILE IS HERE FOR HISTORICAL PURPOSES ONLY 5 | 6 | 7 | 8 | /***************************************************************************** 9 | Copyright (c) 2020 Kendra Little 10 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 11 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 12 | 13 | This script is from the online course https://littlekendra.com/course/ssms-shortcuts-secrets/ 14 | 15 | 16 | NOTE: MICROSOFT NO LONGER SUPPORTS THIS EXTENSION 17 | THIS FILE IS HERE FOR HISTORICAL PURPOSES ONLY 18 | 19 | SQL Server Management Studio extension for Diagnostics 20 | (Currently in preview) 21 | https://www.microsoft.com/en-us/download/details.aspx?id=55516 22 | 23 | *****************************************************************************/ 24 | 25 | 26 | /***************************************************************************** 27 | Problem: Stack Dumps are terrifying 28 | 29 | Solution: SSMS Extension for Diagnostics 30 | *****************************************************************************/ 31 | 32 | 33 | /* Demo: 34 | Make sure the extension is already installed for this version of SSMS 35 | Tools -> SQL Server Diagnostics -> Analyze Dumps 36 | 37 | 38 | Upload a .mdmp file from 39 | C:\MSSQL\DATA\MSSQL13.MSSQLSERVER\MSSQL\Log 40 | */ 41 | 42 | 43 | -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/07-Stupid-Pet-Tricks.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/ssms-shortcuts-secrets/ 7 | 8 | 9 | 10 | 11 | DISCLAIMER: 12 | SERIOUSLY DON'T DO THESE THINGS 13 | THEY ARE ACTUALLY BAD 14 | THAT IS NOT A JOKE 15 | *****************************************************************************/ 16 | 17 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 18 | GO 19 | 20 | 21 | 22 | /***************************************************************************** 23 | Problem: The 'GO' batch terminator is so pushy. 24 | 25 | Bad Solution: Change it 26 | *****************************************************************************/ 27 | 28 | /* Demo: 29 | Tools -> Options (ALT T, O) 30 | Query Execution 31 | Change Batch Separator to: GOO 32 | */ 33 | 34 | 35 | /* Does this work? */ 36 | SELECT * 37 | FROM sys.databases; 38 | GO 39 | 40 | 41 | /* Try it in a new session */ 42 | 43 | 44 | /* Reset the batch separator */ 45 | 46 | 47 | 48 | 49 | /***************************************************************************** 50 | Problem: I hate a table and NOBODY SHOULD SEE IT 51 | 52 | Terrible Solution: Hide it from SSMS 53 | *****************************************************************************/ 54 | 55 | /* This lovely hack is courtesy Kenneth Fisher 56 | https://sqlstudies.com/2017/04/03/hiding-tables-in-ssms-object-explorer-using-extended-properties/ 57 | 58 | As he says, this is strange! 59 | I think the main reason to know about this is just that someone could do it TO you. 60 | */ 61 | 62 | /* Demo: View Application.Cities in Object Explorer. 63 | Then hide it...*/ 64 | 65 | USE WideWorldImporters; 66 | GO 67 | 68 | EXEC sp_addextendedproperty 69 | @name = N'microsoft_database_tools_support', 70 | @value = 'Hide', 71 | @level0type = N'Schema', @level0name = 'Application', 72 | @level1type = N'Table', @level1name = 'Cities'; 73 | GO 74 | 75 | /* Refresh Tables in Object Explorer. 76 | What the...*/ 77 | 78 | /* It still exists and we have permissions to it... */ 79 | SELECT * 80 | FROM sys.objects 81 | WHERE name='Cities'; 82 | GO 83 | 84 | SELECT * 85 | FROM Application.Cities; 86 | GO 87 | 88 | 89 | /* If you wanted to monitor for this, you could use a simple 90 | query like this... 91 | */ 92 | SELECT * 93 | FROM sys.extended_properties 94 | WHERE name='microsoft_database_tools_support'; 95 | GO 96 | 97 | /* 98 | But if you're concerned someone with sysadmin permissions is 99 | going to do this, you may have a human resources problem more than a 100 | monitoring problem. 101 | */ 102 | 103 | /* Remove the extended property */ 104 | EXEC sp_dropextendedproperty 105 | @name = N'microsoft_database_tools_support', 106 | @level0type = N'Schema', @level0name = 'Application', 107 | @level1type = N'Table', @level1name = 'Cities'; 108 | GO 109 | 110 | /* Refresh the table list */ 111 | 112 | 113 | 114 | 115 | 116 | 117 | 118 | 119 | -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/SQLWorkbooks-SSMS-Shortcuts-and-Secrets-Cheat-Sheet.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/ssms_shortcuts_and_secrets/SQLWorkbooks-SSMS-Shortcuts-and-Secrets-Cheat-Sheet.pdf -------------------------------------------------------------------------------- /ssms_shortcuts_and_secrets/sqlworkbooks-ssms-shortcuts-secrets-wallpaper_1920-1080.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/ssms_shortcuts_and_secrets/sqlworkbooks-ssms-shortcuts-secrets-wallpaper_1920-1080.jpg -------------------------------------------------------------------------------- /troubleshooting_blocking_and_deadlocks_for_beginners/03-Deadlock-Basics.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/troubleshooting-blocking-and-deadlocks-for-beginners 7 | *****************************************************************************/ 8 | 9 | RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 10 | GO 11 | 12 | /* The Blocked Process Report is very cool, but it's just blocking. 13 | 14 | If the blocking has to be broken up by the deadlock manager, we can get more details. 15 | 16 | But we have to collect the Deadlock Graph for that. 17 | The deadlock graph is XML. It has two different names, depending on how you collect it: 18 | 19 | In SQLTrace, this is "Deadlock Graph" in the Locks category. 20 | In Extended Events, this is xml_deadlock_report 21 | */ 22 | 23 | 24 | /* In recent versions of SQL Server, the xml_deadlock_report is picked up 25 | by the system_health XEvents session. 26 | But that session collects lots of other events, and it has max_events_limit=5000 27 | If you want to make SURE you get your deadlock graph, it's worth setting up another trace. 28 | */ 29 | 30 | CREATE EVENT SESSION [SW_Deadlock Graph] ON SERVER 31 | ADD EVENT sqlserver.xml_deadlock_report 32 | ADD TARGET package0.event_file(SET filename=N'S:\XEvents\Deadlocks.xel') 33 | WITH (MAX_MEMORY=4096 KB,EVENT_RETENTION_MODE=ALLOW_SINGLE_EVENT_LOSS,MAX_DISPATCH_LATENCY=30 SECONDS, 34 | MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=ON) 35 | GO 36 | 37 | /* Now start the trace */ 38 | ALTER EVENT SESSION [SW_Deadlock Graph] ON SERVER STATE = START; 39 | GO 40 | 41 | 42 | 43 | 44 | /* 45 | Now that it's set up, we lie in wait for a deadlock. 46 | 47 | Oh, look, here comes one now! 48 | */ 49 | 50 | 51 | USE WideWorldImporters; 52 | GO 53 | 54 | /* Run the BEGIN tran and the first statement in this session. 55 | We're taking out a lock on the Countries table */ 56 | WHILE @@TRANCOUNT > 1 ROLLBACK 57 | BEGIN TRAN 58 | 59 | UPDATE Application.Countries 60 | SET LatestRecordedPopulation = LatestRecordedPopulation + 1 61 | WHERE IsoNumericCode = 840; 62 | 63 | 64 | 65 | 66 | /* Stop here and run the SELECT below in session 2. 67 | After it's running, complete this transaction....*/ 68 | 69 | UPDATE Application.StateProvinces 70 | SET LatestRecordedPopulation = LatestRecordedPopulation +1 71 | WHERE StateProvinceCode=N'VA' 72 | COMMIT 73 | GO 74 | 75 | 76 | 77 | /* Select for Session 2. 78 | This gets blocked on the countries table, but it gets a lock on StateProvinces*/ 79 | USE WideWorldImporters; 80 | GO 81 | SELECT CityName, StateProvinceName, sp.LatestRecordedPopulation, CountryName 82 | FROM Application.Cities AS city 83 | JOIN Application.StateProvinces AS sp on 84 | city.StateProvinceID = sp.StateProvinceID 85 | JOIN Application.Countries AS ctry on 86 | sp.CountryID=ctry.CountryID 87 | WHERE sp.StateProvinceName = N'Virginia'; 88 | GO 89 | 90 | 91 | /* Now finish up the transaction in Session 1*/ 92 | 93 | /* Open the extended events file, and find the deadlock graph. 94 | 95 | Double-click on the value in details 96 | Note that it does not contain both updates in the first transaction! 97 | Now show the Deadlock tab 98 | Hover over the circles (processes) 99 | 100 | 101 | 102 | Now head to the slides for a bit 103 | */ 104 | 105 | 106 | 107 | 108 | 109 | 110 | 111 | 112 | 113 | 114 | 115 | 116 | 117 | 118 | /* Create this index, and then re-run the deadlock code to see if it fixes it */ 119 | CREATE INDEX ix_deadlock_killer on Application.Countries (CountryId) INCLUDE (CountryName); 120 | GO -------------------------------------------------------------------------------- /troubleshooting_blocking_and_deadlocks_for_beginners/04-Cleanup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/troubleshooting-blocking-and-deadlocks-for-beginners 7 | 8 | 9 | Cleanup you need to do manually: 10 | Delete trace files from S:\XEvents 11 | Restore database WideWorldImporters (if you want a clean copy) 12 | 13 | This script will: 14 | Reset 'blocked process threshold (s)' to 0 using sp_configure + RECONFIGURE 15 | Kill off session for SW_Oops if he has an open transaction (00-Setup.sql left open) 16 | Delete SQL Agent Jobs: 'SW_Blockee', 'SW_Frank Did It' 17 | Delete SQL Agent Alert: 'SW_Super Simple Blocking Alert' 18 | Delete Operator: SW_DemoOperator 19 | Drop Logins SW_Oops, SW_FrankInProductManagement, SW_ImportantApp 20 | Drop Extended Events Sessions: 21 | 'SW_Blocked Process Report' 22 | 'SW_Deadlock Graph' 23 | *****************************************************************************/ 24 | 25 | use master; 26 | GO 27 | 28 | ------------------------------------------------------------------------------- 29 | --Reset 'blocked process threshold (s)' to 0 using sp_configure + RECONFIGURE 30 | ------------------------------------------------------------------------------- 31 | EXEC sp_configure 'show advanced options', 1; 32 | GO 33 | RECONFIGURE 34 | GO 35 | 36 | 37 | EXEC sp_configure 'blocked process threshold (s)', 0; 38 | GO 39 | RECONFIGURE 40 | GO 41 | 42 | ------------------------------------------------------------------------------- 43 | --Kill off session for SW_Oops if he has an open transaction (00-Setup.sql left open) 44 | ------------------------------------------------------------------------------- 45 | DECLARE @session_id int=NULL, 46 | @dsql NVARCHAR(1000) = N'', 47 | @msg NVARCHAR(1000) = N''; 48 | SELECT @session_id=session_id 49 | FROM sys.dm_exec_sessions where login_name='SW_Oops' 50 | IF @session_id IS NULL 51 | BEGIN 52 | SET @msg = N'No spid found for SW_Oops' 53 | RAISERROR (@msg, 1, 1) WITH NOWAIT; 54 | END 55 | ELSE 56 | BEGIN 57 | SET @dsql= N'KILL ' + cast(@session_id as NVARCHAR(10)); 58 | SET @msg = N'Killing spid ' + cast(@session_id as NVARCHAR(10)) + N' for SW_Oops' 59 | RAISERROR (@msg, 1, 1) WITH NOWAIT; 60 | EXEC sp_executesql @dsql; 61 | END 62 | GO 63 | 64 | 65 | ------------------------------------------------------------------------------- 66 | --Delete SQL Agent Jobs: 'SW_Blockee', 'SW_Frank Did It' 67 | ------------------------------------------------------------------------------- 68 | IF (SELECT COUNT(*) FROM msdb..sysjobs WHERE name=N'SW_Blockee') > 0 69 | exec msdb..sp_delete_job @job_name=N'SW_Blockee'; 70 | GO 71 | 72 | IF (SELECT COUNT(*) FROM msdb..sysjobs WHERE name=N'SW_Frank Did It') > 0 73 | exec msdb..sp_delete_job @job_name=N'SW_Frank Did It'; 74 | GO 75 | 76 | 77 | ------------------------------------------------------------------------------- 78 | --Delete SQL Agent Alert: 'SW_Super Simple Blocking Alert' 79 | ------------------------------------------------------------------------------- 80 | IF (SELECT COUNT(*) from msdb..sysalerts where name = N'SW_Super Simple Blocking Alert') > 0 81 | EXEC msdb.dbo.sp_delete_alert @name=N'SW_Super Simple Blocking Alert' 82 | GO 83 | 84 | ------------------------------------------------------------------------------- 85 | --Delete Operator: SW_DemoOperator 86 | ------------------------------------------------------------------------------- 87 | 88 | IF (SELECT COUNT(*) from msdb..sysoperators where name = N'SW_DemoOperator') > 0 89 | EXEC msdb.dbo.sp_delete_operator @name=N'SW_DemoOperator'; 90 | GO 91 | 92 | ------------------------------------------------------------------------------- 93 | --Drop Logins SW_Oops, SW_FrankInProductManagement, SW_ImportantApp 94 | ------------------------------------------------------------------------------- 95 | IF (SELECT count(*) from sys.sql_logins where name='SW_Oops') > 0 96 | DROP LOGIN SW_Oops; 97 | GO 98 | 99 | IF (SELECT count(*) from sys.sql_logins where name='SW_FrankInProductManagement') > 0 100 | DROP LOGIN SW_FrankInProductManagement; 101 | GO 102 | 103 | IF (SELECT count(*) from sys.sql_logins where name='SW_ImportantApp') > 0 104 | DROP LOGIN SW_ImportantApp; 105 | GO 106 | 107 | ------------------------------------------------------------------------------- 108 | --Drop Extended Events Sessions: 109 | -- 'SW_Blocked Process Report' 110 | -- 'SW_Deadlock Graph' 111 | ------------------------------------------------------------------------------- 112 | IF (SELECT COUNT(*) FROM sys.server_event_sessions where name=N'SW_Blocked Process Report') > 0 113 | DROP EVENT SESSION [SW_Blocked Process Report] ON SERVER 114 | GO 115 | 116 | IF (SELECT COUNT(*) FROM sys.server_event_sessions where name=N'SW_Deadlock Graph') > 0 117 | DROP EVENT SESSION [SW_Deadlock Graph] ON SERVER 118 | GO 119 | -------------------------------------------------------------------------------- /tuning_problem_queries_table_partitioning/00-Setup.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/tuning-problem-queries-in-table-partitioning 7 | 8 | Setup: 9 | Download the database to restore from https://github.com/LitKnd/BabbyNames/releases/tag/v1.1 10 | You must download all four backup files with names like 'BabbyNames_Partitioning_1_of_4.bak.zip'. 11 | Unzip each file, then use them to restore the BabbyNames database. 12 | This database is 23GB after being restored. 13 | You must restore to SQL Server 2016 or a higher version. 14 | *****************************************************************************/ 15 | 16 | RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 17 | GO 18 | 19 | 20 | /******************************************************/ 21 | /* Restore database */ 22 | /******************************************************/ 23 | use master; 24 | GO 25 | IF DB_ID('BabbyNames') IS NOT NULL 26 | BEGIN 27 | ALTER DATABASE BabbyNames SET SINGLE_USER WITH ROLLBACK IMMEDIATE; 28 | END 29 | GO 30 | RESTORE DATABASE BabbyNames FROM 31 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_1_of_4.bak', 32 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_2_of_4.bak', 33 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_3_of_4.bak', 34 | DISK = N'S:\MSSQL\Backup\BabbyNames_Partitioning_4_of_4.bak' 35 | WITH REPLACE; 36 | GO 37 | 38 | /******************************************************/ 39 | /* Create indexes for demos */ 40 | /******************************************************/ 41 | use BabbyNames; 42 | GO 43 | 44 | /* nonclustered rowstore... */ 45 | EXEC evt.logme N'Create index ix_dbo_FirstNameByBirthDate_1976_2015_BirthYear.'; 46 | GO 47 | CREATE INDEX ix_dbo_FirstNameByBirthDate_1966_2015_BirthYear 48 | on dbo.FirstNameByBirthDate_1966_2015 (BirthYear) 49 | WITH (SORT_IN_TEMPDB = ON, DATA_COMPRESSION=ROW); 50 | GO 51 | 52 | EXEC evt.logme N'Create index ix_pt_FirstNameByBirthDate_1976_2015_BirthYear.'; 53 | GO 54 | CREATE INDEX ix_pt_FirstNameByBirthDate_1966_2015_BirthYear 55 | on pt.FirstNameByBirthDate_1966_2015 (BirthYear) 56 | WITH (SORT_IN_TEMPDB = ON, DATA_COMPRESSION=ROW); 57 | GO 58 | 59 | EXEC evt.logme N'Create index ix_dbo_FirstNameByBirthDate_1966_2015_FirstNameId.'; 60 | GO 61 | 62 | CREATE INDEX ix_dbo_FirstNameByBirthDate_1966_2015_FirstNameId 63 | on dbo.FirstNameByBirthDate_1966_2015 (FirstNameId) 64 | WITH (SORT_IN_TEMPDB = ON, DATA_COMPRESSION=ROW); 65 | GO 66 | 67 | EXEC evt.logme N'Create index ix_pt_FirstNameByBirthDate_1966_2015_FirstNameId.'; 68 | GO 69 | 70 | CREATE INDEX ix_pt_FirstNameByBirthDate_1966_2015_FirstNameId 71 | on pt.FirstNameByBirthDate_1966_2015 (FirstNameId) 72 | WITH (SORT_IN_TEMPDB = ON, DATA_COMPRESSION=ROW); 73 | GO 74 | 75 | 76 | 77 | EXEC evt.logme N'Create index col_pt_FirstNameByBirthDate_1966_2015.'; 78 | GO 79 | CREATE NONCLUSTERED COLUMNSTORE INDEX col_pt_FirstNameByBirthDate_1966_2015 80 | on pt.FirstNameByBirthDate_1966_2015 81 | ( FakeBirthDateStamp, FirstNameByBirthDateId, StateCode, FirstNameId, Gender); 82 | GO 83 | -------------------------------------------------------------------------------- /tuning_problem_queries_table_partitioning/01-Aggregator.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/tuning-problem-queries-in-table-partitioning 7 | *****************************************************************************/ 8 | 9 | RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 10 | GO 11 | 12 | 13 | USE BabbyNames; 14 | GO 15 | 16 | /* These are the two tables that we'll be using... */ 17 | exec sp_help 'dbo.FirstNameByBirthDate_1966_2015'; 18 | GO 19 | exec sp_help 'pt.FirstNameByBirthDate_1966_2015'; 20 | GO 21 | 22 | /********************************************************/ 23 | /* Problem Query: The aggregator */ 24 | /********************************************************/ 25 | 26 | 27 | /* Run these with actual plans enabled. 28 | Compare the estimated cost 29 | Compare the query time stats 30 | Show why the columnstore index is drunk here. 31 | */ 32 | SELECT 33 | BirthYear, 34 | COUNT(*) as NameCount 35 | FROM dbo.FirstNameByBirthDate_1966_2015 36 | WHERE BirthYear BETWEEN 2001 and 2015 37 | GROUP BY BirthYear 38 | ORDER BY COUNT(*) DESC; 39 | GO 40 | 41 | SELECT 42 | BirthYear, 43 | COUNT(*) as NameCount 44 | FROM pt.FirstNameByBirthDate_1966_2015 45 | WHERE BirthYear BETWEEN 2001 and 2015 46 | GROUP BY BirthYear 47 | ORDER BY COUNT(*) DESC; 48 | GO 49 | 50 | /* OK, let's just not use the columnstore. 51 | Let's use the partitioned rowstore index on BirthYear. */ 52 | SELECT 53 | BirthYear, 54 | COUNT(*) as NameCount 55 | FROM pt.FirstNameByBirthDate_1966_2015 56 | WHERE BirthYear BETWEEN 2001 and 2015 57 | GROUP BY BirthYear 58 | ORDER BY COUNT(*) DESC 59 | OPTION (IGNORE_NONCLUSTERED_COLUMNSTORE_INDEX); 60 | GO 61 | 62 | /* It's still a bit slower */ 63 | /* Head back to the slides to explain why the partitioned index is different */ 64 | 65 | 66 | 67 | 68 | 69 | 70 | 71 | 72 | 73 | 74 | /************************************************************************* 75 | Fixes 76 | *************************************************************************/ 77 | 78 | /*************************** 79 | FIX 1 - NONALIGNED INDEX 80 | ***************************/ 81 | 82 | /* We can create a "non-aligned", non-partitioned index on our partitioned 83 | table. Just specify a filegroup rather than a partition scheme */ 84 | /* I'm giving it a short (terrible) name just to make it easy to identify in the execution plan */ 85 | /* This takes 1.5 minutes to create. */ 86 | CREATE INDEX nonaligned 87 | on pt.FirstNameByBirthDate_1966_2015 (BirthYear) 88 | WITH (SORT_IN_TEMPDB = ON) 89 | ON [PRIMARY]; 90 | GO 91 | 92 | 93 | /* Now we can get a stream aggregate .... */ 94 | SELECT 95 | BirthYear, 96 | COUNT(*) as NameCount 97 | FROM pt.FirstNameByBirthDate_1966_2015 98 | WHERE BirthYear BETWEEN 2001 and 2015 99 | GROUP BY BirthYear 100 | ORDER BY COUNT(*) DESC 101 | OPTION (IGNORE_NONCLUSTERED_COLUMNSTORE_INDEX); 102 | GO 103 | 104 | /* But we've lost the ability to do partition level operations: 105 | switch any partition in 106 | switch any partition out 107 | truncate any partition 108 | 109 | We have to drop or disable all non-aligned indexes to do ANY partition level operation. 110 | */ 111 | 112 | TRUNCATE TABLE pt.FirstNameByBirthDate_1966_2015 113 | WITH (PARTITIONS (1 TO 4)); 114 | GO 115 | 116 | DROP INDEX IF EXISTS nonaligned 117 | ON pt.FirstNameByBirthDate_1966_2015; 118 | GO 119 | 120 | /*************************** 121 | FIX 1 - NOT SO GREAT. 122 | ***************************/ 123 | 124 | 125 | /*************************** 126 | FIX 2 - QUERY REWRITE TO GET 127 | PARTION ELIMINATION 128 | ***************************/ 129 | 130 | 131 | /* We can rewrite the query to get partition elimination. 132 | We're still going to have to do the hash aggregate, but we'll 133 | do it for fewer partitions */ 134 | 135 | /* Run these with actual plans on. 136 | Look at how many actual partitions were used in the plan.*/ 137 | SELECT 138 | BirthYear, 139 | COUNT(*) as NameCount 140 | FROM pt.FirstNameByBirthDate_1966_2015 141 | WHERE 142 | FakeBirthDateStamp >= CAST('2001-01-01' AS DATETIME2(0)) and 143 | FakeBirthDateStamp < CAST('2016-01-01' AS DATETIME2(0)) 144 | GROUP BY BirthYear 145 | ORDER BY COUNT(*) DESC 146 | OPTION (IGNORE_NONCLUSTERED_COLUMNSTORE_INDEX); 147 | GO 148 | 149 | SELECT 150 | BirthYear, 151 | COUNT(*) as NameCount 152 | FROM pt.FirstNameByBirthDate_1966_2015 153 | WHERE 154 | FakeBirthDateStamp >= CAST('2001-01-01' AS DATETIME2(0)) and 155 | FakeBirthDateStamp < CAST('2016-01-01' AS DATETIME2(0)) 156 | GROUP BY BirthYear 157 | ORDER BY COUNT(*) DESC; 158 | GO -------------------------------------------------------------------------------- /tuning_problem_queries_table_partitioning/02-Min_Max.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/tuning-problem-queries-in-table-partitioning 7 | *****************************************************************************/ 8 | 9 | RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 10 | GO 11 | 12 | 13 | 14 | USE BabbyNames; 15 | GO 16 | 17 | /********************************************************/ 18 | /* Problem: MIN / MAX get slow */ 19 | /********************************************************/ 20 | 21 | 22 | /* Run these with actual plans enabled. 23 | Note the differences between the plans. 24 | It knows the query against the partitioned table will be more expensive. 25 | Look at elapsed time in each plan. 26 | Query 1: look at the seek operator and explain why that was fast. 27 | Query 2: How many partitions were actually used? 28 | */ 29 | /* Why is the second query slower? */ 30 | SELECT MAX(FirstNameId) AS max_val 31 | FROM dbo.FirstNameByBirthDate_1966_2015 32 | GO 33 | 34 | SELECT MAX(FirstNameId) AS max_val 35 | FROM pt.FirstNameByBirthDate_1966_2015 36 | OPTION (IGNORE_NONCLUSTERED_COLUMNSTORE_INDEX) 37 | GO 38 | 39 | 40 | 41 | 42 | 43 | 44 | 45 | 46 | 47 | 48 | 49 | 50 | /* MIN has the same issue (although of course a different resulting value) */ 51 | SELECT MIN(FirstNameId) AS min_val 52 | FROM pt.FirstNameByBirthDate_1966_2015 53 | OPTION (IGNORE_NONCLUSTERED_COLUMNSTORE_INDEX) 54 | GO 55 | 56 | 57 | 58 | 59 | /* To the slides, to talk this through! */ 60 | 61 | 62 | 63 | 64 | /************************************************************************* 65 | Fixes 66 | *************************************************************************/ 67 | 68 | /*************************** 69 | FIX 1 - Non-Aligned Index 70 | ***************************/ 71 | 72 | /* We can create a "non-aligned", non-partitioned index on our partitioned 73 | table. Just specify a filegroup rather than a partition scheme */ 74 | /* I'm giving it a short (terrible) name just to make it easy to identify in the execution plan */ 75 | /* This takes 1.5 minutes to create. */ 76 | CREATE INDEX nonaligned 77 | on pt.FirstNameByBirthDate_1966_2015 (FirstNameId) 78 | WITH (SORT_IN_TEMPDB = ON) 79 | ON [PRIMARY]; 80 | GO 81 | 82 | 83 | /* Now we get the "non-partitioned" plan .... */ 84 | SELECT MAX(FirstNameId) AS max_val 85 | FROM pt.FirstNameByBirthDate_1966_2015; 86 | GO 87 | 88 | /* But we've lost the ability to do partition level operations: 89 | switch any partition in 90 | switch any partition out 91 | truncate any partition 92 | 93 | We have to drop or disable all non-aligned indexes to do ANY partition level operation. 94 | */ 95 | 96 | TRUNCATE TABLE pt.FirstNameByBirthDate_1966_2015 97 | WITH (PARTITIONS (1 TO 4)); 98 | GO 99 | 100 | DROP INDEX IF EXISTS nonaligned 101 | ON pt.FirstNameByBirthDate_1966_2015; 102 | GO 103 | 104 | 105 | /*************************** 106 | FIX 2 - Query rewrite 107 | ***************************/ 108 | /* OK, let's practice the recommended workaround from the Connect Item */ 109 | 110 | /* Our solution relies on the $partition function. 111 | This computes which partition data is in... here's a simple example */ 112 | SELECT $partition.pf_fnbd(FakeBirthDateStamp) as partition_number, 113 | FakeBirthDateStamp, 114 | FirstNameByBirthDateId, 115 | BirthYear, 116 | FirstNameId, 117 | Gender 118 | FROM pt.FirstNameByBirthDate_1966_2015 119 | WHERE FakeBirthDateStamp = CAST('1966-01-05 18:29:00' AS DATETIME2(0)); 120 | GO 121 | 122 | 123 | 124 | /* Testing out the pattern in https://connect.microsoft.com/SQLServer/feedback/details/240968/partition-table-using-min-max-functions-and-top-n-index-selection-and-performance */ 125 | /* We're just looking at partition #s 41, 42, 43 here */ 126 | /* We can use the function in interesting ways. 127 | Look at the plan for this query... it does a very efficient backward scan in each partition */ 128 | SELECT MAX(max_val) 129 | FROM 130 | ( VALUES (41), (42), (43) ) as partitiontable(num) /* 3 row table from table value constructor */ 131 | CROSS APPLY 132 | (SELECT MAX(FirstNameId) as max_val 133 | FROM pt.FirstNameByBirthDate_1966_2015 134 | /* CROSS APPLY lets us join to the table value constructor in here */ 135 | WHERE $partition.pf_fnbd(FakeBirthDateStamp) = partitiontable.num 136 | ) AS o; 137 | GO 138 | 139 | 140 | 141 | /* What if we have a changing number of partitions over time? */ 142 | 143 | /* We can use the partition function "fanout" and a numbers 144 | table to construct a table with one row for each partition number, like this */ 145 | SELECT n.Num 146 | FROM sys.partition_functions AS pf 147 | JOIN ref.Numbers as n on n.Num <= pf.fanout 148 | WHERE 149 | pf.name='pf_fnbd'; 150 | GO 151 | 152 | 153 | /* So we can get an automatic peek into each partition which has rows using this... */ 154 | /* Note: joining to a system table prevents parallelism, so I'm doing this as a two-step 155 | query and putting the value for @fanout into a variable */ 156 | DECLARE @fanout int 157 | SELECT @fanout = fanout 158 | FROM sys.partition_functions pf 159 | WHERE pf.name='pf_fnbd' 160 | 161 | SELECT MAX(max_val) 162 | FROM ( 163 | SELECT Num 164 | FROM ref.Numbers 165 | WHERE Num <= @fanout 166 | ) as partitiontable(num) 167 | CROSS APPLY 168 | (select MAX(FirstNameId) as max_val 169 | from pt.FirstNameByBirthDate_1966_2015 170 | where $partition.pf_fnbd(FakeBirthDateStamp) = partitiontable.num 171 | ) as o; 172 | GO 173 | 174 | 175 | /* It's not pretty. 176 | Don't like it? 177 | Vote up the bug! 178 | https://connect.microsoft.com/SQLServer/feedback/details/240968/partition-table-using-min-max-functions-and-top-n-index-selection-and-performance 179 | */ 180 | 181 | 182 | /*************************** 183 | FIX 3 - Columnstore 184 | ***************************/ 185 | 186 | 187 | SELECT MAX(FirstNameId) AS max_val 188 | FROM pt.FirstNameByBirthDate_1966_2015; 189 | GO 190 | -------------------------------------------------------------------------------- /tuning_problem_queries_table_partitioning/03-Blocked.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/tuning-problem-queries-in-table-partitioning 7 | *****************************************************************************/ 8 | 9 | RAISERROR ('Did you mean to run the whole thing?', 20, 1) WITH LOG; 10 | GO 11 | 12 | USE BabbyNames; 13 | GO 14 | 15 | /********************************************************/ 16 | /* Problem: Unexpected blocking */ 17 | /********************************************************/ 18 | 19 | 20 | /* Start this query in another session. 21 | This will take out a lock on the partition holding 2015 data */ 22 | USE BabbyNames; 23 | GO 24 | BEGIN TRAN 25 | DECLARE @updateval DATETIME2(0)='2010-01-01 03:49:00' 26 | 27 | UPDATE pt.FirstNameByBirthDate_1966_2015 28 | SET StateCode = 'ZZ' 29 | WHERE FakeBirthDateStamp=@updateval 30 | and FirstNameId = 67092; 31 | 32 | 33 | 34 | 35 | /* This query should only need to read from one partition. 36 | Start it up in this session. */ 37 | SELECT COUNT(*) 38 | FROM pt.FirstNameByBirthDate_1966_2015 39 | WHERE FakeBirthDateStamp >= '2000-01-01 00:00:00.0' 40 | AND FakeBirthDateStamp < '2000-01-02 00:00:00.0'; 41 | GO 42 | 43 | 44 | /* Confirm that it is blocked in a third session. 45 | Why? 46 | */ 47 | exec sp_WhoIsActive @get_plans=1; 48 | GO 49 | 50 | /* Look at the predicate on the columnstore operator in the plan 51 | There's a convert_implicit 52 | And there's @1 and @1 53 | 54 | Cancel the blocked query 55 | */ 56 | 57 | 58 | 59 | /* This is a simple query, so SQL Server is automatically parameterizing those dates. 60 | It sees it needs to make them a DATETIME2, but it defaults to making them DATETIME2(7) 61 | The column in the table is a DATETIME2(0). 62 | When you compare a more precise value to a less precise value, SQL Server has to down-sample the less-precise value 63 | So it's having to check every partition to see if the dates we want could be in there. 64 | */ 65 | 66 | 67 | 68 | 69 | 70 | /* Get an estimated plan for this corrected query. 71 | Look at the seek predicate which magically appeared. 72 | Then run the query and look at the actual plan / 73 | actual partitions accessed. */ 74 | SELECT COUNT(*) 75 | FROM pt.FirstNameByBirthDate_1966_2015 76 | WHERE FakeBirthDateStamp > CAST('2000-01-01 00:00:00.0' AS DATETIME2(0)) 77 | AND FakeBirthDateStamp <= CAST('2000-01-02 00:00:00.0' AS DATETIME2(0)) 78 | GO 79 | 80 | 81 | 82 | 83 | 84 | 85 | 86 | 87 | 88 | /* This also works fine */ 89 | DECLARE @FakeBirthDateStampStart DATETIME2(0) = '2000-01-01 00:00:00.0', 90 | @FakeBirthDateStampEnd DATETIME2(0) = '2000-01-02 00:00:00.0'; 91 | 92 | SELECT COUNT(*) 93 | FROM pt.FirstNameByBirthDate_1966_2015 94 | WHERE FakeBirthDateStamp > @FakeBirthDateStampStart 95 | AND FakeBirthDateStamp <= @FakeBirthDateStampEnd 96 | GO 97 | 98 | 99 | 100 | -------------------------------------------------------------------------------- /why_creating_an_index_can_slow_down_a_query/actual-plan-after-adding-index.sqlplan: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/why_creating_an_index_can_slow_down_a_query/actual-plan-after-adding-index.sqlplan -------------------------------------------------------------------------------- /why_creating_an_index_can_slow_down_a_query/actual-plan-before-adding-index.sqlplan: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/LitKnd/SQLWorkbooks/ba4a01854e5a1dead646fe6882d839007a60444f/why_creating_an_index_can_slow_down_a_query/actual-plan-before-adding-index.sqlplan -------------------------------------------------------------------------------- /xevents_sqlchallenge/01_Extended-Events_Problem.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/sqlchallenge-create-an-extended-events-trace/ 7 | 8 | Setup: 9 | Download BabbyNames.bak.zip (42 MB database backup) 10 | https://github.com/LitKnd/BabbyNames/releases/tag/1.3 11 | 12 | This database can be restored to SQL Server 2008R2 or higher, BUT this challenge is 13 | SQL Server 2016+ 14 | 15 | This is the CHALLENGE File 16 | *****************************************************************************/ 17 | 18 | /* ✋🏻 Doorstop ✋🏻 */ 19 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 20 | GO 21 | 22 | 23 | /**************************************************** 24 | Restore database 25 | ****************************************************/ 26 | SET NOCOUNT, ANSI_NULLS, QUOTED_IDENTIFIER ON 27 | GO 28 | 29 | 30 | --Adjust drive / folder locations for the restore 31 | USE master; 32 | GO 33 | IF DB_ID('BabbyNames2017') IS NOT NULL 34 | BEGIN 35 | ALTER DATABASE BabbyNames2017 36 | SET SINGLE_USER 37 | WITH ROLLBACK IMMEDIATE; 38 | END 39 | GO 40 | RESTORE DATABASE BabbyNames2017 41 | FROM DISK=N'S:\MSSQL\Backup\BabbyNames.bak' 42 | WITH 43 | MOVE 'BabbyNames' TO 'S:\MSSQL\Data\BabbyNames2017.mdf', 44 | MOVE 'BabbyNames_log' TO 'S:\MSSQL\Data\BabbyNames2017_log.ldf', 45 | REPLACE, 46 | RECOVERY; 47 | GO 48 | 49 | ALTER DATABASE BabbyNames2017 SET QUERY_STORE = ON 50 | GO 51 | ALTER DATABASE BabbyNames2017 SET QUERY_STORE (OPERATION_MODE = READ_WRITE) 52 | GO 53 | ALTER DATABASE BabbyNames2017 SET COMPATIBILITY_LEVEL = 140; 54 | GO 55 | 56 | 57 | /**************************************************** 58 | Set up the condition we will trace for 59 | ****************************************************/ 60 | USE BabbyNames2017; 61 | GO 62 | 63 | CREATE OR ALTER PROCEDURE dbo.FreezeMe 64 | @TotalNameCountLimit INT 65 | AS 66 | SELECT 67 | FirstName, 68 | FirstReportYear as SoloReportYear, 69 | TotalNameCount 70 | FROM ref.FirstName 71 | WHERE 72 | FirstReportYear = LastReportYear 73 | and TotalNameCount > @TotalNameCountLimit 74 | ORDER BY TotalNameCount DESC; 75 | GO 76 | 77 | CREATE INDEX ix_hereandthengone on ref.FirstName (TotalNameCount) 78 | INCLUDE ( FirstReportYear, LastReportYear, FirstName) 79 | GO 80 | 81 | EXEC dbo.FreezeMe @TotalNameCountLimit = 30; 82 | GO 83 | 84 | declare @qid INT, @pid INT; 85 | 86 | SELECT TOP (1) 87 | @qid = qsp.query_id, 88 | @pid = qsp.plan_id 89 | FROM sys.query_store_plan AS qsp 90 | JOIN sys.query_store_query AS qsq on qsp.query_id=qsq.query_id 91 | WHERE qsq.object_id = OBJECT_ID('dbo.FreezeMe') 92 | and qsp.last_force_failure_reason = 0 93 | ORDER BY qsp.last_compile_start_time DESC; 94 | 95 | EXEC sys.sp_query_store_force_plan @query_id=@qid, @plan_id=@pid; 96 | GO 97 | 98 | ALTER INDEX ix_hereandthengone on ref.FirstName DISABLE; 99 | GO 100 | 101 | 102 | EXEC dbo.FreezeMe @TotalNameCountLimit = 40; 103 | GO 104 | 105 | 106 | 107 | /**************************************************** 108 | SQLChallenge! 109 | ****************************************************/ 110 | 111 | /* We should see that one of the query plans for this object has a 112 | "last_force_failure_reason_desc" of NO_INDEX after the setup script. 113 | This is what we want to get more information about. */ 114 | SELECT 115 | qsp.query_id, 116 | qsp.plan_id, 117 | qsp.is_trivial_plan, 118 | qsp.is_forced_plan, 119 | qsp.last_execution_time, 120 | qsp.last_force_failure_reason_desc, 121 | cast(qsp.query_plan AS XML) as query_plan 122 | FROM sys.query_store_plan AS qsp 123 | JOIN sys.query_store_query AS qsq on qsp.query_id=qsq.query_id 124 | WHERE qsq.object_id = OBJECT_ID('dbo.FreezeMe') 125 | ORDER BY qsp.last_compile_start_time DESC; 126 | GO 127 | 128 | /* SQL Challenge: 129 | 130 | Set up an Extended Events trace to capture failed forced plans. 131 | After you have the trace running, run this command to reproduce the failed 132 | forced plan, then review the trace to make sure it caught the incident. 133 | 134 | Also collect the global fields: session_id, sql_text 135 | Use an event_file target 136 | 137 | */ 138 | 139 | 140 | --Test your trace using these queries. 141 | --What appears in the trace, and what does not? 142 | EXEC dbo.FreezeMe @TotalNameCountLimit = 10000; 143 | GO 144 | 145 | EXEC dbo.FreezeMe @TotalNameCountLimit = 100 WITH RECOMPILE; 146 | GO 147 | 148 | ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; 149 | 150 | EXEC dbo.FreezeMe @TotalNameCountLimit = 150; 151 | GO 152 | 153 | EXEC dbo.FreezeMe @TotalNameCountLimit = 500; 154 | GO 155 | -------------------------------------------------------------------------------- /xevents_sqlchallenge/02_Extended-Events_Solution.sql: -------------------------------------------------------------------------------- 1 | /***************************************************************************** 2 | Copyright (c) 2020 Kendra Little 3 | This work is licensed under a Creative Commons Attribution-NonCommercial-ShareAlike 4.0 International License. 4 | http://creativecommons.org/licenses/by-nc-sa/4.0/ 5 | 6 | This script is from the online course https://littlekendra.com/course/sqlchallenge-create-an-extended-events-trace/ 7 | 8 | Setup: 9 | Download BabbyNames.bak.zip (42 MB database backup) 10 | https://github.com/LitKnd/BabbyNames/releases/tag/1.3 11 | 12 | This database can be restored to SQL Server 2008R2 or higher, BUT this challenge is 13 | SQL Server 2016+ 14 | 15 | This is the SOLUTION File 16 | *****************************************************************************/ 17 | 18 | /* ✋🏻 Doorstop ✋🏻 */ 19 | RAISERROR(N'Did you mean to run the whole thing?',20,1) WITH LOG; 20 | GO 21 | 22 | /* 23 | New session - 24 | The wizard that's not called a wizard 25 | 26 | Search for word force. Hmmm. 27 | 28 | Expand channels, add debug. Hmmm. 29 | 30 | Change search term: query_store 31 | 32 | Add event: query_store_plan_forcing_failed 33 | 34 | 35 | Add global fields: session_id, sql_text 36 | Configure event_file target 37 | 38 | */ 39 | 40 | 41 | --Scripted trace: 42 | 43 | CREATE EVENT SESSION [Query Store Plan Forcing Failed] ON SERVER 44 | ADD EVENT qds.query_store_plan_forcing_failed( 45 | ACTION(sqlserver.session_id,sqlserver.sql_text)) 46 | ADD TARGET package0.event_file(SET filename=N'S:\XEvents\query_store_plan_forcing_failed.xel') 47 | WITH (MAX_MEMORY=4096 KB, 48 | EVENT_RETENTION_MODE=ALLOW_SINGLE_EVENT_LOSS, 49 | MAX_DISPATCH_LATENCY=5 SECONDS /* This defaults to 30, setting to 5 just for testing */ , 50 | MAX_EVENT_SIZE=0 KB,MEMORY_PARTITION_MODE=NONE,TRACK_CAUSALITY=OFF,STARTUP_STATE=OFF) 51 | GO 52 | 53 | 54 | ALTER EVENT SESSION [Query Store Plan Forcing Failed] ON SERVER STATE = START 55 | GO 56 | 57 | 58 | --Test your trace using these queries. 59 | --What appears in the trace, and what does not? 60 | 61 | --First statement 62 | EXEC dbo.FreezeMe @TotalNameCountLimit = 10000; 63 | GO 64 | 65 | --Second statement 66 | EXEC dbo.FreezeMe @TotalNameCountLimit = 100 WITH RECOMPILE; 67 | GO 68 | 69 | ALTER DATABASE SCOPED CONFIGURATION CLEAR PROCEDURE_CACHE; 70 | GO 71 | 72 | --Third statement 73 | EXEC dbo.FreezeMe @TotalNameCountLimit = 150; 74 | GO 75 | 76 | 77 | --Fourth statement 78 | EXEC dbo.FreezeMe @TotalNameCountLimit = 500; 79 | GO 80 | 81 | exec sp_recompile 'dbo.FreezeMe'; 82 | GO 83 | --Bonus statement 84 | EXEC dbo.FreezeMe @TotalNameCountLimit = 750; 85 | GO 86 | 87 | 88 | 89 | /* Stop the trace */ 90 | 91 | ALTER EVENT SESSION [Query Store Plan Forcing Failed] ON SERVER STATE = STOP 92 | GO 93 | 94 | 95 | /* Clean up */ 96 | DROP EVENT SESSION [Query Store Plan Forcing Failed] ON SERVER; 97 | GO --------------------------------------------------------------------------------