├── Advanced SQL Puzzles ├── Advanced SQL Puzzles DDL.sql ├── Advanced SQL Puzzles Solutions.sql ├── Advanced SQL Puzzles.pdf ├── Part II │ ├── 01 Factorials Recursion.sql │ ├── 02 All Permutations Recursion Bit Mask.sql │ ├── 02 All Permutations Recursion.sql │ ├── 02 All Permutations While Loop.sql │ ├── 03 Growing Numbers Recursion.sql │ ├── 03 Growing Numbers While Loop.sql │ ├── 04 Non-Adjacent Numbers Recursion.sql │ ├── 04 Non-Adjacent Numbers While Loop.sql │ ├── 05 Add The Numbers Up Recursion.sql │ ├── 06 Permutations Of 0 And 1 While Loop.sql │ ├── 07 Permutations 1 Through 10 Cross Join.sql │ ├── 07 Permutations 1 Through 10 Recurssion Bit Mask.sql │ ├── 08 Four Vehicles Combinations Cross Join.sql │ ├── 09 Find The Spaces Recursion.sql │ ├── 10 Seating Chart.sql │ ├── 11 Count The Groupings.sql │ ├── 12 Double Or Add 1 Recursion.sql │ ├── 13 Pascals Triangle Recursion.sql │ ├── 14 Josephus Problem Sequence.sql │ ├── 15 High Low Card Game Random Sequence.sql │ ├── 16 Monty Hall Simulation Random Numbers.sql │ ├── 17 Dice Roll Game Recursion.sql │ ├── 18 Birthday Problem Random Numbers.sql │ ├── 19 Random Walk Sequence.sql │ ├── 20 Markov Chain Recursion.sql │ ├── 21 100 Prisoners Recursion.sql │ ├── 22 Non-Overlapping Sets.sql │ ├── 23 Knight's Tour │ └── readme.md ├── Recursion Examples │ ├── Associates Recursion.sql │ ├── DeGrouping Recursion.sql │ ├── Double the Number Recursion.sql │ ├── Factorials Recursion.sql │ ├── Fibonacci Sequence Recursion.sql │ ├── Floor and Ceiling Caps Recursion.sql │ ├── Group Concatenation Recursion.sql │ ├── Growing Numbers Recursion.sql │ ├── Managers and Employees Recursion.sql │ ├── Mandelbrot Set Recursion.sql │ ├── Markov Chain Recursion.sql │ ├── Numbers Table Recursion.sql │ ├── Permutations Bit Mask Recursion.sql │ ├── Permutations Recursion.sql │ ├── String Split Each Character Recursion.sql │ ├── String Split Recursion.sql │ ├── Sudoku Recursion.sql │ ├── Traveling Salesman Recursion.sql │ └── readme.md └── readme.md ├── Database Articles ├── Advanced SQL Joins │ ├── 01 - Introduction.md │ ├── 02 - SQL Query Processing Order.md │ ├── 03 - Table Types.md │ ├── 04 - Equi, Theta, and Natural Joins.md │ ├── 05 - Inner Join.md │ ├── 06 - Outer Joins.md │ ├── 07 - Full Outer Join.md │ ├── 08 - Cross Join.md │ ├── 09 - Semi and Anti Joins.md │ ├── 10 - Any, All, and Some.md │ ├── 11 - Self Join.md │ ├── 12 - Relational Division.md │ ├── 13 - Set Operations.md │ ├── 14 - Join Algorithms.md │ ├── 15 - Exists.md │ ├── 16 - Complex Joins.md │ ├── Sample Data.md │ ├── images │ │ ├── SQL Query Processing Order XML.xml │ │ ├── SQLQueryProcessingOrderPage.png │ │ └── readme.md │ └── readme.md ├── Azure Data Factory Metadata Demo │ ├── Customer_1.txt │ ├── Customer_2.txt │ ├── Customer_3.txt │ ├── Data Factory Metadata Demo PDF.pdf │ ├── Data Factory Metadata Demo Powerpoint.pptx │ ├── Data Factory SQL DDL Scripts.sql │ └── readme.md ├── Azure Databricks Hive Demo │ ├── Azure Databricks Spark Hive Demo PDF.pdf │ ├── Azure Databricks Spark Hive Demo Powerpoint.pptx │ ├── Parts.csv │ ├── Shipments.csv │ ├── Suppliers.csv │ ├── SuppliersAndParts.dbc │ ├── SuppliersAndPartsDDL.sql │ └── readme.md ├── Behavior Of Nulls │ ├── images │ │ ├── Truth_Tables_Three_Valued_Logic.png │ │ └── readme.md │ └── readme.md ├── Database Certifications │ └── README.MD ├── Database Dependencies │ ├── Database_Dependency_Analysis.xlsx │ ├── README.MD │ └── SQL Scripts │ │ ├── 01_Cross_Database_Dependencies.sql │ │ ├── 02_Cross_Schema_Dependencies.sql │ │ ├── 03_Invalid_Stored_Procedures.sql │ │ ├── 04_Numbered_Stored_Procedures.sql │ │ ├── 05_Ambiguous_References.sql │ │ ├── 06_Part_Naming_Conventions.sql │ │ ├── 07_Part_Naming_Conventions_Caller_Dependent.sql │ │ ├── 08_Dropping_Objects.sql │ │ ├── 09_Dropping_Objects_Then_Recreating.sql │ │ ├── 10_Self_Referencing_Objects.sql │ │ ├── 11_Object_Aliases.sql │ │ ├── 12_Schemabindings.sql │ │ ├── 13_Synonyms.sql │ │ ├── 14_Triggers_DML.sql │ │ ├── 15_Triggers_DDL_Database_Level.sql │ │ ├── 16_Triggers_DDL_Server_Level_Table_Insert.sql │ │ ├── 17_Partition_Functions.sql │ │ ├── 18_Defaults_and_Rules.sql │ │ ├── 19_Contracts_and_Queues_and_Message_Types.sql │ │ ├── 20_Sequences.sql │ │ ├── 21_User_Defined_Data_Types.sql │ │ ├── 22_User_Defined_Table_Types.sql │ │ ├── 23_Check_Constraints.sql │ │ ├── 24_Foreign_Key_Constraints.sql │ │ ├── 25_Computed_Columns.sql │ │ ├── 26_Masked_Functions.sql │ │ ├── 27_Indexes_Table.sql │ │ ├── 28_Indexes_Filtered_NonClustered.sql │ │ ├── 29_Indexes_Filtered_XML.sql │ │ ├── 30_Statistics_Filtered.sql │ │ ├── 31_XML_Schema_Collections.sql │ │ ├── 32_XML_Methods.sql │ │ ├── Additional SQL Scripts │ │ ├── 01_Create_Databases_Schemas_Tables.sql │ │ ├── 02_Database_Dependencies_Deployment_sqlcmd.sql │ │ ├── 03_Database_Dependencies_Analysis.sql │ │ ├── 04_Kill_Open_Sessions.sql │ │ └── README.MD │ │ └── README.MD ├── Truth Tables │ └── readme.md └── readme.md └── readme.md /Advanced SQL Puzzles/Advanced SQL Puzzles.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Advanced SQL Puzzles/Advanced SQL Puzzles.pdf -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/01 Factorials Recursion.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Factorials 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | The script creates a temporary table called #Numbers that contains the 9 | factorials of a range of numbers specified by the variable @vTotalNumbers. 10 | The script uses a common table expression (CTE) with recursion to calculate the factorials, 11 | starting with the number one and incrementing by one until the value of @vTotalNumbers is reached. 12 | The results of the CTE are then inserted into the #Numbers table and displayed at the end. 13 | The OPTION (MAXRECURSION 0) setting ensures that there is no limit to the recursion level. 14 | 15 | **********************************************************************/ 16 | 17 | --------------------- 18 | --------------------- 19 | --Tables used in script 20 | DROP TABLE IF EXISTS #Numbers; 21 | GO 22 | 23 | --------------------- 24 | --------------------- 25 | --Declare and set and variables 26 | DECLARE @vTotalNumbers INTEGER = 10; 27 | 28 | --------------------- 29 | --------------------- 30 | --Create #Numbers table using recursion 31 | WITH cte_Factorial (Number, Factorial) AS 32 | ( 33 | SELECT 1, 34 | 1 35 | UNION ALL 36 | SELECT Number + 1 AS Number, 37 | (Number + 1) * Factorial AS Factorial 38 | FROM cte_Factorial 39 | WHERE Number < @vTotalNumbers 40 | ) 41 | SELECT Number, 42 | Factorial 43 | INTO #Numbers 44 | FROM cte_Factorial 45 | OPTION (MAXRECURSION 0);--A value of 0 means no limit to the recursion level; 46 | GO 47 | 48 | --------------------- 49 | --------------------- 50 | --Display the results 51 | SELECT * 52 | FROM #Numbers; 53 | GO 54 | 55 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/02 All Permutations Recursion Bit Mask.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | All Permutations 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/07/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | The script generates all the permutations of numbers from 1 to @vTotalNumbers (inclusive). 9 | It first creates a table called #Numbers, which contains a column of numbers from 1 to @vTotalNumbers. 10 | Then, it uses a recursive CTE to generate all the permutations by iterating through the #Numbers 11 | table and concatenating the numbers to form unique permutations. The output is saved in the temporary 12 | table #Permutations, and the results can be viewed by running a SELECT statement on it. The script 13 | uses bitwise operators to speed up the calculation, but it can take a significant amount of time 14 | to generate all permutations, especially with larger values of @vTotalNumbers. 15 | 16 | **********************************************************************/ 17 | 18 | --------------------- 19 | --------------------- 20 | --Tables used 21 | DROP TABLE IF EXISTS #Numbers; 22 | DROP TABLE IF EXISTS #Permutations; 23 | GO 24 | 25 | --------------------- 26 | --------------------- 27 | --Declare and set variables 28 | DECLARE @vTotalNumbers BIGINT = 3; 29 | 30 | --------------------- 31 | --------------------- 32 | --Create a #Numbers table using recursion 33 | WITH cte_Numbers (Number) 34 | AS ( 35 | SELECT 1 AS Number 36 | UNION ALL 37 | SELECT Number + 1 38 | FROM cte_Numbers 39 | WHERE Number < @vTotalNumbers 40 | ) 41 | SELECT 42 | Number 43 | INTO #Numbers 44 | FROM cte_Numbers 45 | OPTION (MAXRECURSION 0);--A value of 0 means no limit to the recursion level 46 | 47 | --------------------- 48 | --------------------- 49 | --Generate the Permutations using recursion 50 | WITH cte_Numbers AS 51 | ( 52 | SELECT CAST(Number AS VARCHAR(MAX)) AS Number 53 | FROM #Numbers 54 | ), 55 | cte_Bitmasks AS 56 | ( 57 | SELECT 58 | Number, 59 | CAST(POWER(2, ROW_Number() OVER (ORDER BY Number) - 1) AS INT) AS Bitmask 60 | FROM cte_Numbers 61 | ), 62 | cte_Permutations AS 63 | ( 64 | SELECT Number AS Permutation, 65 | Bitmask 66 | FROM cte_Bitmasks 67 | 68 | UNION ALL 69 | 70 | SELECT p.Permutation + ',' + b.Number, 71 | p.Bitmask ^ b.Bitmask 72 | FROM cte_Permutations p INNER JOIN 73 | cte_Bitmasks b ON p.Bitmask ^ b.Bitmask > p.Bitmask 74 | ) 75 | SELECT ROW_NUMBER() OVER (ORDER BY GETDATE()) AS Id, 76 | Permutation 77 | INTO #Permutations 78 | FROM cte_Permutations 79 | WHERE Bitmask = POWER(2, (SELECT COUNT(*) FROM cte_Numbers)) - 1; 80 | 81 | --------------------- 82 | --------------------- 83 | --Display the results 84 | SELECT @vTotalNumbers AS MaxNumber, 85 | Permutation 86 | FROM #Permutations 87 | ORDER BY 2; 88 | GO 89 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/02 All Permutations Recursion.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | All Permutations 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script creates all the possible permutations of a set of numbers (from one to a user-specified value) 9 | using a recursive CTE. It creates a #Numbers table using recursion and then uses that table to populate 10 | the #Permutations table with all possible permutations. It then uses a WHERE clause to limit the output 11 | to only the permutations of the same length as the longest permutation. The results are then ordered by the permutation. 12 | 13 | **********************************************************************/ 14 | 15 | --------------------- 16 | --------------------- 17 | --Tables used 18 | DROP TABLE IF EXISTS #Numbers; 19 | DROP TABLE IF EXISTS #Permutations; 20 | GO 21 | 22 | --------------------- 23 | --------------------- 24 | --Declare and set variables 25 | DECLARE @vTotalNumbers INTEGER = 3; 26 | 27 | --------------------- 28 | --------------------- 29 | --Create a #Numbers table using recursion 30 | WITH cte_Numbers (Number) 31 | AS ( 32 | SELECT 1 AS Number 33 | UNION ALL 34 | SELECT Number + 1 35 | FROM cte_Numbers 36 | WHERE Number < @vTotalNumbers 37 | ) 38 | SELECT 39 | Number 40 | INTO #Numbers 41 | FROM cte_Numbers 42 | OPTION (MAXRECURSION 0);--A value of 0 means no limit to the recursion level 43 | 44 | --------------------- 45 | --------------------- 46 | --Populate the #Permutations table with all possible permutations 47 | WITH cte_Permutations (Permutation, Ids, Depth) 48 | AS 49 | ( 50 | SELECT CAST(Number AS VARCHAR(MAX)), 51 | CAST(CONCAT(Number,';') AS VARCHAR(MAX)), 52 | 1 AS Depth 53 | FROM #Numbers 54 | UNION ALL 55 | SELECT CONCAT(a.Permutation,',',b.Number), 56 | CONCAT(a.Ids,b.Number,';'), 57 | a.Depth + 1 58 | FROM cte_Permutations a, 59 | #Numbers b 60 | WHERE a.Depth < @vTotalNumbers AND 61 | a.Ids NOT LIKE CONCAT('%',b.Number,';%') 62 | ) 63 | SELECT Permutation 64 | INTO #Permutations 65 | FROM cte_Permutations; 66 | GO 67 | --------------------- 68 | --------------------- 69 | --Display the results 70 | SELECT * 71 | FROM #Permutations 72 | WHERE LEN(Permutation) = (SELECT MAX(LEN(Permutation)) FROM #Permutations) 73 | ORDER BY 1; 74 | GO 75 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/02 All Permutations While Loop.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | All Permutations 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/07/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script generates all permutations of a given set of numbers using a while loop. 9 | It starts by creating a #Numbers table with a specified number of integers using a recursive CTE. 10 | Then, it creates an empty #Permutations table and seeds it with the initial values from the #Numbers table. 11 | Then, it enters a while loop, and in each iteration of the loop, it first performs a DELETE statement to 12 | keep the number of records in the #Permutations table minimal. Then, it uses an INSERT statement 13 | to add new permutations to the #Permutations table by combining the current permutations with the 14 | remaining numbers from the #Numbers table. The while loop continues until the number of rows 15 | affected by the DELETE statement is 0. Finally, it selects and displays the final 16 | permutations from the #Permutations table. 17 | 18 | **********************************************************************/ 19 | 20 | --------------------- 21 | --------------------- 22 | --Tables used 23 | DROP TABLE IF EXISTS #Numbers; 24 | DROP TABLE IF EXISTS #Permutations; 25 | GO 26 | 27 | --------------------- 28 | --------------------- 29 | --Set the number of permutations to create 30 | DECLARE @vTotalNumbers BIGINT = 3; 31 | 32 | --------------------- 33 | --------------------- 34 | --Create a #Numbers table using recursion 35 | WITH cte_Numbers (Number) 36 | AS ( 37 | SELECT 1 AS Number 38 | UNION ALL 39 | SELECT Number + 1 40 | FROM cte_Numbers 41 | WHERE Number < @vTotalNumbers 42 | ) 43 | SELECT 44 | Number 45 | INTO #Numbers 46 | FROM cte_Numbers 47 | OPTION (MAXRECURSION 0);--A value of 0 means no limit to the recursion level 48 | 49 | --------------------- 50 | --------------------- 51 | --Create the #Permutations table and provide initial seed 52 | SELECT CAST(Number AS VARCHAR(100)) AS Permutation, 53 | GETDATE() AS InsertDate 54 | INTO #Permutations 55 | FROM #Numbers; 56 | 57 | --------------------- 58 | --------------------- 59 | --Populate the #Permutations table 60 | WHILE @@ROWCOUNT > 0 61 | BEGIN 62 | 63 | --Used to keep the table record count to a minimal 64 | DELETE #Permutations WHERE InsertDate < (SELECT MAX(InsertDate) FROM #Permutations); 65 | 66 | INSERT INTO #Permutations (Permutation, InsertDate) 67 | SELECT CONCAT(a.Permutation, ',', b.Number), 68 | GETDATE() 69 | FROM #Permutations a CROSS JOIN 70 | #Numbers b 71 | WHERE CAST(REPLACE(RIGHT(a.Permutation,2),',','') AS INTEGER) <> b.Number 72 | AND 73 | CHARINDEX(CONCAT(b.Number,','),CONCAT(a.Permutation,',')) = 0; 74 | END; 75 | 76 | --------------------- 77 | --------------------- 78 | --Display the results 79 | SELECT @vTotalNumbers AS MaxNumber, 80 | Permutation 81 | FROM #Permutations 82 | ORDER BY Permutation; 83 | GO 84 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/03 Growing Numbers Recursion.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Growing Numbers 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script finds all possible growing numbers from a set of integers within a specified range. 9 | For example, given the input 1, 2, 3, 4, and 5. It will produce the following output: 10 | 1 11 | 12 12 | 123 13 | 1234 14 | 12345 15 | 16 | The script creates a temporary table called #GrowingNumbers and uses a recursive CTE to populate it. 17 | The script initializes a variable, @vTotalNumbers, with the count of integers in the set. 18 | The CTE, cte_GrowingNumbers, generates all possible growing numbers from the set of integers. 19 | The CTE starts by selecting the individual integers from the #Numbers table and concatenating them to 20 | form a single growing number. Then, it recursively joins itself with the #Numbers table, adding one 21 | integer at a time while ensuring that the next integer added is a successive number. 22 | 23 | The script then inserts the results of the CTE into the #GrowingNumbers table and uses a SELECT 24 | statement to display the contents of the table filtered by the condition that the first digit of 25 | the number must be equal to the minimum number in the set. 26 | 27 | The script will run properly if the following conditions are met: 28 | The first number is a single-digit 29 | All digits are successive, and there are no gaps in the numbers 30 | Two of the numbers cannot be two digits (i.e., 10 and 11) 31 | 32 | **********************************************************************/ 33 | 34 | --------------------- 35 | --------------------- 36 | --Tables used 37 | DROP TABLE IF EXISTS #Numbers; 38 | DROP TABLE IF EXISTS #GrowingNumbers; 39 | GO 40 | 41 | --------------------- 42 | --------------------- 43 | --For this puzzle, I manually create the #Numbers table to provide special testing cases (rather than using recursion) 44 | CREATE TABLE #Numbers 45 | ( 46 | Number INTEGER UNIQUE NOT NULL 47 | ); 48 | GO 49 | 50 | INSERT INTO #Numbers (Number) VALUES 51 | (1),(2),(3),(4),(5); --Passes 52 | --(6),(7),(8),(9),(10); --Passes 53 | --(5),(7),(8),(9),(10); --Does Not Pass (Gap between 5 and 7) 54 | --(7),(8),(9),(10),(11); --Does Not Pass (Two numbers greater than 10) 55 | --(10),(11),(12); --Does Not Pass (The lowest number is not a single digit, and the set contains two numbers greater than 10) 56 | GO 57 | 58 | --------------------- 59 | --------------------- 60 | --Declare and set variables 61 | DECLARE @vTotalNumbers INTEGER = (SELECT COUNT(*) FROM #Numbers); 62 | 63 | --------------------- 64 | --------------------- 65 | --Create the #GrowingNumbers table using recursion 66 | WITH cte_GrowingNumbers (Number, Ids, Depth) 67 | AS 68 | ( 69 | SELECT CAST(Number AS VARCHAR(MAX)) AS Number, 70 | CAST(CONCAT(Number,'') AS VARCHAR(MAX)) AS Ids, 71 | 1 AS Depth 72 | FROM #Numbers 73 | UNION ALL 74 | SELECT CONCAT(a.Number,b.Number), 75 | CONCAT(a.Ids,b.Number), 76 | a.Depth + 1 77 | FROM cte_GrowingNumbers a, 78 | #Numbers b 79 | WHERE a.Depth < @vTotalNumbers AND 80 | CAST(RIGHT(a.Ids,1) AS INTEGER) + 1 = b.Number 81 | ) 82 | SELECT Number 83 | INTO #GrowingNumbers 84 | FROM cte_GrowingNumbers; 85 | GO 86 | 87 | --------------------- 88 | --------------------- 89 | --Display the results 90 | SELECT * 91 | FROM #GrowingNumbers 92 | WHERE LEFT(Number,1) = (SELECT MIN(Number) FROM #Numbers); 93 | GO 94 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/03 Growing Numbers While Loop.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Growing Numbers 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/07/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script finds all possible growing numbers from a set of integers within a specified range. 9 | For example, given the inputs 1, 2, 3, 4, and 5. It will produce the following output: 10 | 1 11 | 12 12 | 123 13 | 1234 14 | 12345 15 | 16 | The script creates a temporary table called #GrowingNumbers and uses a WHILE loop to populate it. 17 | The script initializes two variables, @vStart and @vEnd, to represent the range of integers 18 | used in the permutations. It then enters a WHILE loop that runs as long as @vStart is less than or 19 | equal to @vEnd. In each iteration of the loop, it selects the maximum value from the #GrowingNumbers table, 20 | concatenates it with the current value of @vStart, and inserts the resulting value into the #GrowingNumbers table. 21 | It then increments @vStart by 1. After the loop has completed, the script uses a SELECT statement to display 22 | the contents of the #GrowingNumbers table. 23 | 24 | **********************************************************************/ 25 | 26 | --------------------- 27 | --------------------- 28 | --Tables used 29 | DROP TABLE IF EXISTS #Permutations; 30 | GO 31 | 32 | --------------------- 33 | --------------------- 34 | --Create #Permutations table 35 | CREATE TABLE #Permutations 36 | ( 37 | Number BIGINT UNIQUE NOT NULL 38 | ); 39 | GO 40 | 41 | --------------------- 42 | --------------------- 43 | --Declare and set variables 44 | DECLARE @vStart INT = 1; 45 | DECLARE @vEnd INT = 5; 46 | DECLARE @number BIGINT; 47 | 48 | --------------------- 49 | --------------------- 50 | --Populate the #Permutations table 51 | WHILE @vStart <= @vEnd 52 | BEGIN 53 | 54 | SELECT @number = MAX(Number) FROM #Permutations; 55 | 56 | INSERT INTO #Permutations 57 | SELECT CAST(CONCAT(@number,@vStart) AS BIGINT); 58 | 59 | SET @vStart = @vStart + 1; 60 | 61 | END 62 | GO 63 | --------------------- 64 | --------------------- 65 | --Display the results 66 | SELECT * FROM #Permutations; 67 | GO 68 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/04 Non-Adjacent Numbers Recursion.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Non-Adjacent Numbers 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script is used to find all permutations of a set of integers in a specific range that do not have any adjacent numbers. 9 | The script creates three temporary tables: #Numbers, #Permutations, and #PermutationsMaxCharIndex. It first populates the 10 | #Numbers table with a set of integers, and then uses a recursive CTE to generate all possible permutations of those integers 11 | and store them in the #Permutations table, along with a flag column indicating whether the permutation has any adjacent numbers or not. 12 | 13 | The script then creates a new CTE called cte_AdjacentNumbers, which finds all pairs of adjacent numbers in the set. 14 | It then uses this CTE to populate the #PermutationsMaxCharIndex table with the maximum index of each adjacent number pair in each permutation. 15 | 16 | Finally, the script updates the #Permutations table to set the flag column to 1 for any permutation with an adjacent number pair 17 | by joining it with the #PermutationsMaxCharIndex table and checking the MaxCharIndex column. The script then uses a SELECT statement 18 | to display the contents of the #Permutations table, ordered by the flag column. 19 | 20 | **********************************************************************/ 21 | 22 | --------------------- 23 | --------------------- 24 | --Tables used 25 | DROP TABLE IF EXISTS #Numbers; 26 | DROP TABLE IF EXISTS #Permutations; 27 | DROP TABLE IF EXISTS #PermutationsMaxCharIndex; 28 | GO 29 | 30 | --------------------- 31 | --------------------- 32 | --For this puzzle, I manually create the #Numbers table to provide special testing cases (rather than using recursion) 33 | CREATE TABLE #Numbers 34 | ( 35 | Number INT NOT NULL 36 | ); 37 | GO 38 | 39 | INSERT INTO #Numbers (Number) VALUES 40 | --(1),(2),(3),(4);--,(4),(5),(6),(7),(8),(9),(10); --Correct results 41 | (5),(7),(9),(11);--,(4),(5),(6),(7),(8),(9),(10); --Correct results 42 | GO 43 | 44 | --------------------- 45 | --------------------- 46 | --Create the #Permutations table using recursion 47 | WITH cte_Numbers AS 48 | ( 49 | SELECT CAST(Number AS VARCHAR(MAX)) AS Number 50 | FROM #Numbers 51 | ), 52 | cte_Bitmasks AS 53 | ( 54 | SELECT 55 | Number, 56 | CAST(POWER(2, ROW_Number() OVER (ORDER BY Number) - 1) AS INT) AS Bitmask 57 | FROM cte_Numbers 58 | ), 59 | cte_Permutations AS 60 | ( 61 | SELECT Number AS Permutation, 62 | Bitmask 63 | FROM cte_Bitmasks 64 | 65 | UNION ALL 66 | 67 | SELECT p.Permutation + ',' + b.Number, 68 | p.Bitmask ^ b.Bitmask 69 | FROM cte_Permutations p INNER JOIN 70 | cte_Bitmasks b ON p.Bitmask ^ b.Bitmask > p.Bitmask 71 | ) 72 | SELECT Permutation, 73 | 0 AS HasAdjacentNumbers 74 | INTO #Permutations 75 | FROM cte_Permutations 76 | WHERE Bitmask = POWER(2, (SELECT COUNT(*) FROM cte_Numbers)) - 1; 77 | 78 | --------------------- 79 | --------------------- 80 | --Create the #PermutationsMaxCharIndex table 81 | WITH cte_AdjacentNumbers AS 82 | ( 83 | SELECT 'A' AS Id, CONCAT(a.Number,',',b.Number) AS AdjacentNumbers 84 | FROM #Numbers a INNER JOIN 85 | #Numbers b ON a.Number = (b.Number + 1) 86 | UNION 87 | SELECT 'B', CONCAT(b.Number,',',a.Number) --note this is the reciprocal of the above AdjacentNumbers column 88 | FROM #Numbers a INNER JOIN 89 | #Numbers b ON a.Number = (b.Number + 1) 90 | ) 91 | SELECT a.Permutation, 92 | MAX(CHARINDEX(CONCAT(b.AdjacentNumbers,','),CONCAT(a.Permutation,','))) AS MaxCharIndex 93 | INTO #PermutationsMaxCharIndex 94 | FROM #Permutations a CROSS JOIN 95 | cte_AdjacentNumbers b 96 | GROUP BY a.Permutation; 97 | 98 | --------------------- 99 | --------------------- 100 | --Update the #Permutations table using #PermutationsMaxCharIndex 101 | UPDATE #Permutations 102 | SET HasAdjacentNumbers = 1 103 | FROM #Permutations a INNER JOIN 104 | #PermutationsMaxCharIndex b on a.Permutation = b.Permutation 105 | WHERE MaxCharIndex > 0; 106 | GO 107 | 108 | --------------------- 109 | --------------------- 110 | --View the results 111 | SELECT * 112 | FROM #Permutations 113 | ORDER BY 2; 114 | GO 115 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/04 Non-Adjacent Numbers While Loop.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Non-Adjacent Numbers 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script is used to find all permutations of a set of integers that are not 9 | adjacent to each other. The script creates a temporary table called #Permutations, 10 | which is initially seeded with the integers from a table called #Numbers. The script 11 | then enters a WHILE loop that runs as long as there are still permutations to be generated. 12 | In each iteration of the loop, it selects all permutations from the #Permutations table, 13 | concatenates them with the current value of a number from the #Numbers table, and insert the 14 | resulting value into the #Permutations table. It also checks to ensure that the new permutation 15 | doesn't have any adjacent numbers. The script uses a SELECT statement to display the contents of 16 | the #Permutations table after the loop has completed. 17 | 18 | **********************************************************************/ 19 | 20 | --------------------- 21 | --------------------- 22 | --Tables used 23 | DROP TABLE IF EXISTS #Numbers; 24 | DROP TABLE IF EXISTS #Permutations; 25 | GO 26 | 27 | --------------------- 28 | --------------------- 29 | --Create #Permutations table 30 | CREATE TABLE #Permutations 31 | ( 32 | InsertDate DATETIME DEFAULT GETDATE() NOT NULL, 33 | Id INTEGER Identity(1,1) NOT NULL, 34 | Permutation VARCHAR(100) NOT NULL 35 | ); 36 | GO 37 | 38 | --------------------- 39 | --------------------- 40 | --For this puzzle, I manually create the #Numbers table to provide special testing cases (rather than using recursion) 41 | CREATE TABLE #Numbers 42 | ( 43 | Number INTEGER NOT NULL 44 | ); 45 | GO 46 | 47 | INSERT INTO #Numbers (Number) VALUES 48 | (1),(2),(3),(4);--,(4),(5),(6),(7),(8),(9),(10); --Correct results 49 | --(5),(7),(9),(11);--,(4),(5),(6),(7),(8),(9),(10); --Correct results 50 | GO 51 | 52 | --------------------- 53 | --------------------- 54 | --Seed the #Permutations puzzle 55 | INSERT INTO #Permutations (Permutation) 56 | SELECT CAST(Number as VARCHAR(100)) FROM #Numbers; 57 | GO 58 | 59 | --------------------- 60 | --------------------- 61 | --Populate the #Permutations table 62 | WHILE @@ROWCOUNT > 0 63 | BEGIN 64 | 65 | --Used to keep the table record count to a minimal 66 | DELETE #Permutations WHERE InsertDate < (SELECT MAX(InsertDate) FROM #Permutations); 67 | 68 | INSERT INTO #Permutations (Permutation) 69 | SELECT CONCAT(a.Permutation, ',', b.Number) 70 | FROM #Permutations a CROSS JOIN 71 | #Numbers b 72 | WHERE 73 | CAST(REPLACE(RIGHT(a.Permutation,2),',','') AS INTEGER) <> b.Number + 1 74 | AND 75 | CAST(REPLACE(RIGHT(a.Permutation,2),',','') AS INTEGER) <> B.Number - 1 76 | --AND 77 | --CHARINDEX(CONCAT(',',b.Number,','),CONCAT(',',a.Permutation,',')) = 0; 78 | AND 79 | CHARINDEX(CONCAT(b.Number,','),CONCAT(a.Permutation,',')) = 0;--479306 80 | END 81 | GO 82 | --------------------- 83 | --------------------- 84 | --Display the results 85 | SELECT * 86 | FROM #Permutations; 87 | GO 88 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/06 Permutations Of 0 And 1 While Loop.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Permutations of 0 and 1 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script creates a temporary table #Permutations and inserts 0 and 1 as initial values. 9 | It then declares a variable @vPermutationLength, which is used to set the length of the permutation string. 10 | Then, using a while loop, it repeatedly concatenates the current permutations in the table 11 | to create new permutations until the maximum length of the permutation column in the table 12 | equals the value of @vPermutationLength. Finally, it selects and displays distinct permutations 13 | of the desired length from the #Permutations table, ordered by the permutation values. 14 | 15 | Given the input of 0 and 1 and a @vPermutationLength of 3, it will produce the following output: 16 | 000, 001, 010, 011, 100, 101, 110, 111 17 | 18 | **********************************************************************/ 19 | 20 | ------------------------------- 21 | ------------------------------- 22 | --Tables used 23 | DROP TABLE IF EXISTS #Permutations; 24 | GO 25 | 26 | ------------------------------- 27 | ------------------------------- 28 | --Create and Populate the #Permutations table 29 | CREATE TABLE #Permutations 30 | ( 31 | Permutation VARCHAR(MAX) 32 | ); 33 | GO 34 | 35 | INSERT INTO #Permutations (Permutation) VALUES ('0'),('1'); 36 | GO 37 | ------------------------------- 38 | ------------------------------- 39 | --Declare and set variables 40 | --Modify this variable with the length of the string you want. 41 | DECLARE @vPermutationLength INTEGER = 3 42 | 43 | ------------------------------- 44 | ------------------------------- 45 | --Populate the #Permutations using a WHILE loop 46 | WHILE (SELECT MAX(LEN(Permutation)) FROM #Permutations) <= @vPermutationLength 47 | BEGIN 48 | 49 | INSERT INTO #Permutations (Permutation) 50 | SELECT CONCAT(a.Permutation,b.Permutation) 51 | FROM #Permutations a CROSS JOIN 52 | #Permutations b; 53 | 54 | END; 55 | 56 | ------------------------------- 57 | ------------------------------- 58 | --Display the Results 59 | SELECT DISTINCT LEFT(Permutation, @vPermutationLength) AS Permutation 60 | FROM #Permutations 61 | WHERE LEN(Permutation) = @vPermutationLength 62 | ORDER BY 1; 63 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/07 Permutations 1 Through 10 Cross Join.sql: -------------------------------------------------------------------------------- 1 | /*--------------------------------------------------------------------------------------------- 2 | Scott Peters 3 | Permutations 1 Through 10 (Cross Join) 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script generates permutations of digits from 1 to 10. It uses a table called #Numbers 9 | which is populated with the numbers 1 through 10. The script then uses CROSS JOINs to 10 | join the #Numbers table multiple times to generate permutations of various lengths 11 | (two digits, three digits, four digits, etc.) with the result set in the format of a concatenated 12 | string (e.g. "1,2,3"). The final query in each block filters out the permutations where 13 | the same number is repeated in the permutation. The script can be modified to generate 14 | permutations of any desired length by adding or removing CROSS JOINs and adjusting the 15 | number of columns in the SELECT statement's CONCAT function. 16 | 17 | */--------------------------------------------------------------------------------------------- 18 | 19 | ------------------------------- 20 | ------------------------------- 21 | --Tables used 22 | DROP TABLE IF EXISTS #Numbers; 23 | GO 24 | ------------------------------- 25 | ------------------------------- 26 | --Create #Numbers table and populate 27 | SELECT Number 28 | INTO #Numbers 29 | FROM (VALUES (1), (2), (3), (4)) n(Number); 30 | GO 31 | 32 | ------------------------------- 33 | ------------------------------- 34 | --Two digits 35 | SELECT CONCAT(a.Number,',',b.Number) AS Permutation 36 | FROM #Numbers a INNER JOIN 37 | #Numbers b on a.Number <> b.Number; 38 | GO 39 | 40 | --Two digits (Version 2) 41 | SELECT CONCAT(a.Number,',',b.Number) AS Permutation 42 | FROM #Numbers a CROSS JOIN 43 | #Numbers b 44 | WHERE a.Number NOT IN (b.Number) 45 | ORDER BY 1; 46 | GO 47 | 48 | ------------------------------- 49 | ------------------------------- 50 | --Three digits 51 | SELECT CONCAT(a.Number,',',b.Number,',',c.Number) AS Permutation 52 | FROM #Numbers a CROSS JOIN 53 | #Numbers b CROSS JOIN 54 | #Numbers c 55 | WHERE a.Number NOT IN (b.Number, c.Number) AND 56 | b.Number NOT IN (c.Number) 57 | ORDER BY 1; 58 | GO 59 | 60 | ------------------------------- 61 | ------------------------------- 62 | --Four digits 63 | SELECT CONCAT(a.Number,',',b.Number,',',c.Number,',',d.Number) AS Permutation 64 | FROM #Numbers a CROSS JOIN 65 | #Numbers b CROSS JOIN 66 | #Numbers c CROSS JOIN 67 | #Numbers d 68 | WHERE a.Number NOT IN (b.Number, c.Number, d.Number) AND 69 | b.Number NOT IN (c.Number, d.Number) AND 70 | c.Number NOT IN (d.Number) 71 | ORDER BY 1; 72 | GO 73 | 74 | ----And so on and so forth for 5,6,7..... 75 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/07 Permutations 1 Through 10 Recurssion Bit Mask.sql: -------------------------------------------------------------------------------- 1 | /*-------------------------------------------------------------------------------------------------------- 2 | Scott Peters 3 | Permutations 1 Through 10 (Bit Mask) 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script generates permutations of a set of numbers using a bitmask. The script starts by 9 | declaring a variable for the length of numbers that will be used in the permutations and then 10 | creates a table called #Numbers that is populated with a set of numbers. The script then uses 11 | common table expressions (CTEs) and bitwise operators to generate permutations of the numbers 12 | in the #Numbers table and stores them in a table called #Permutations. The script also creates 13 | another table called #PermutationsPosition that determines the position of commas in the permutations. 14 | Finally, the script selects distinct permutations of a specific length, specified by the @vLengthNumbers 15 | variable, and displays the results. 16 | 17 | */-------------------------------------------------------------------------------------------------------- 18 | 19 | ------------------------------- 20 | ------------------------------- 21 | --Tables used 22 | DROP TABLE IF EXISTS #Numbers; 23 | DROP TABLE IF EXISTS #Permutations; 24 | DROP TABLE IF EXISTS #PermutationsPosition; 25 | GO 26 | 27 | ------------------------------- 28 | ------------------------------- 29 | --Declare and set the variables 30 | DECLARE @vLengthNumbers INTEGER = 3; 31 | 32 | ------------------------------- 33 | ------------------------------- 34 | --Create #Numbers table and populate 35 | SELECT Number 36 | INTO #Numbers 37 | FROM 38 | --(VALUES (1), (2), (3)) n(Number); 39 | --(VALUES (10), (21), (32)) n(Number); 40 | (VALUES (1), (2), (3), (4)) n(Number); 41 | --(VALUES (1), (2), (3), (4), (5)) n(Number); 42 | --(VALUES (1), (2), (3), (4), (5), (6), (7), (8), (9), (10)) n(Number); 43 | 44 | ------------------------------- 45 | ------------------------------- 46 | --Create #Permutations table and populate 47 | WITH cte_Numbers AS 48 | ( 49 | SELECT CAST(Number AS VARCHAR(MAX)) AS Number 50 | FROM #Numbers 51 | ), 52 | cte_Bitmasks AS 53 | ( 54 | SELECT 55 | Number, 56 | CAST(POWER(2, ROW_Number() OVER (ORDER BY Number) - 1) AS INT) AS Bitmask 57 | FROM cte_Numbers 58 | ), 59 | cte_Permutations AS 60 | ( 61 | SELECT Number AS Permutation, 62 | Bitmask 63 | FROM cte_Bitmasks 64 | 65 | UNION ALL 66 | 67 | SELECT p.Permutation + ',' + b.Number, 68 | p.Bitmask ^ b.Bitmask 69 | FROM cte_Permutations p INNER JOIN 70 | cte_Bitmasks b ON p.Bitmask ^ b.Bitmask > p.Bitmask 71 | ) 72 | SELECT ROW_NUMBER() OVER (ORDER BY GETDATE()) AS Id, 73 | Permutation 74 | INTO #Permutations 75 | FROM cte_Permutations 76 | WHERE Bitmask = POWER(2, (SELECT COUNT(*) FROM cte_Numbers)) - 1 77 | 78 | ------------------------------- 79 | ------------------------------- 80 | --Creates table #PermutationsPosition 81 | --Determines the position of commas 82 | ;WITH cte_CAST AS 83 | ( 84 | SELECT Id, CAST(Permutation AS VARCHAR(20)) AS Permutation FROM #Permutations 85 | ), 86 | cte_Anchor AS 87 | ( 88 | SELECT Id, 89 | Permutation, 90 | 1 AS Starts, 91 | CHARINDEX(',', Permutation) AS Position 92 | FROM cte_CAST 93 | UNION ALL 94 | SELECT Id, 95 | Permutation, 96 | Position + 1, 97 | CHARINDEX(',', Permutation, Position + 1) 98 | FROM cte_Anchor 99 | WHERE Position > 0 100 | ) 101 | SELECT *, 102 | SUBSTRING(Permutation, Starts, CASE WHEN Position > 0 THEN Position - Starts ELSE LEN(Permutation) END) Token, 103 | ROW_NUMBER() OVER (PARTITION BY Id ORDER BY Starts) AS RowNumber 104 | INTO #PermutationsPosition 105 | FROM cte_Anchor 106 | ORDER BY Permutation, Starts; 107 | 108 | ------------------------------- 109 | ------------------------------- 110 | --Display the results 111 | SELECT DISTINCT 112 | LEFT(Permutation,Starts) AS Permutation 113 | FROM #PermutationsPosition 114 | WHERE RowNumber = @vLengthNumbers; 115 | GO 116 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/09 Find The Spaces Recursion.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Find The Spaces 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/07/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to find the spaces in a given string and determine their start and position points. 9 | The script starts by creating a table called #Strings that stores a set of strings. The script then uses a common 10 | table expression (CTE) called cte_CAST to cast the strings in the #Strings table to VARCHAR(200) and a CTE called 11 | cte_Anchor to find the spaces in the strings recursively. The cte_Anchor CTE uses the CHARINDEX function to find 12 | the position of the space character in the string and the Position column to find the next space in the 13 | string recursively. The script also uses the SUBSTRING function to extract the word between spaces and the LEN function and REPLACE 14 | function to find the total number of spaces in the string. The script then uses the ROW_NUMBER() function to assign 15 | a unique row number to each space found and displays the results. 16 | 17 | **********************************************************************/ 18 | 19 | ------------------------------- 20 | ------------------------------- 21 | --Tables Used 22 | DROP TABLE IF EXISTS #Strings; 23 | GO 24 | 25 | ------------------------------- 26 | ------------------------------- 27 | --Create table #Quotes 28 | SELECT * 29 | INTO #Strings 30 | FROM (VALUES(1,'SELECT EmpID, MngrID FROM Employees;'),(2,'SELECT * FROM Transactions;')) n(Id,String); 31 | GO 32 | 33 | ------------------------------- 34 | ------------------------------- 35 | --Display the results using recursion 36 | ;WITH cte_CAST AS 37 | ( 38 | SELECT Id, CAST(String AS VARCHAR(200)) AS String FROM #Strings 39 | ), 40 | cte_Anchor AS 41 | ( 42 | SELECT Id, 43 | String, 44 | 1 AS Starts, 45 | CHARINDEX(' ', String) AS Position 46 | FROM cte_CAST 47 | UNION ALL 48 | SELECT Id, 49 | String, 50 | Position + 1, 51 | CHARINDEX(' ', String, Position + 1) 52 | FROM cte_Anchor 53 | WHERE Position > 0 54 | ) 55 | SELECT ROW_NUMBER() OVER (PARTITION BY Id ORDER BY Starts) AS RowNumber, 56 | *, 57 | SUBSTRING(String, Starts, CASE WHEN Position > 0 THEN Position - Starts ELSE LEN(String) END) Word, 58 | LEN(String) - LEN(REPLACE(String,' ','')) AS TotalSpaces 59 | FROM cte_Anchor 60 | ORDER BY Id, Starts; 61 | GO 62 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/10 Seating Chart.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Seating Chart 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | The script then uses several SQL statements to analyze the data in the #SeatingChart table. 9 | The first query uses the LEAD() window function to find the gaps in the seat numbers and 10 | returns the gap start and gap end values. 11 | 12 | The second query uses a common table expression (CTE) and the ROW_NUMBER() function to find 13 | the missing seat numbers by ranking them and calculating the difference 14 | between each seat number and its rank. The last query uses the COUNT() function and 15 | a CASE statement to determine the number of odd and even seat numbers in the #SeatingChart table. 16 | 17 | **********************************************************************/ 18 | 19 | -------------- 20 | -------------- 21 | --Tables Used 22 | DROP TABLE IF EXISTS #SeatingChart; 23 | GO 24 | 25 | -------------- 26 | -------------- 27 | --Create and populate #SeatingChart 28 | CREATE TABLE #SeatingChart 29 | ( 30 | SeatNumber INTEGER PRIMARY KEY 31 | ); 32 | GO 33 | 34 | INSERT INTO #SeatingChart VALUES 35 | (7),(13),(14),(15),(27),(28),(29),(30),(31),(32),(33),(34),(35),(52),(53),(54); 36 | GO 37 | 38 | -------------- 39 | -------------- 40 | --Place a value of 0 in the SeatingChart table 41 | INSERT INTO #SeatingChart VALUES (0); 42 | GO 43 | 44 | -------------- 45 | -------------- 46 | --Gap start and gap end 47 | SELECT GapStart + 1 AS GapStart, 48 | GapEnd - 1 AS GapEnd 49 | FROM 50 | ( 51 | SELECT SeatNumber AS GapStart, 52 | LEAD(SeatNumber,1,0) OVER (ORDER BY SeatNumber) AS GapEnd, 53 | LEAD(SeatNumber,1,0) OVER (ORDER BY SeatNumber) - SeatNumber AS Gap 54 | FROM #SeatingChart 55 | ) a 56 | WHERE Gap > 1; 57 | 58 | --Missing Numbers 59 | WITH cte_Rank 60 | AS 61 | ( 62 | SELECT SeatNumber, 63 | ROW_NUMBER() OVER (ORDER BY SeatNumber) AS RowNumber, 64 | SeatNumber - ROW_NUMBER() OVER (ORDER BY SeatNumber) AS Rnk 65 | FROM #SeatingChart 66 | WHERE SeatNumber > 0 67 | ) 68 | SELECT MAX(Rnk) AS MissingNumbers FROM cte_Rank; 69 | 70 | --Odd and even number count 71 | SELECT (CASE SeatNumber%2 WHEN 1 THEN 'Odd' WHEN 0 THEN 'Even' END) AS Modulus, 72 | COUNT(*) AS [Count] 73 | FROM #SeatingChart 74 | GROUP BY (CASE SeatNumber%2 WHEN 1 THEN 'Odd' WHEN 0 THEN 'Even' END); 75 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/11 Count The Groupings.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Count the Groupings 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | The script creates two temporary tables: #Groupings and #Groupings2. 9 | The #Groupings table contains test case information, including a step number, 10 | test case name, and status (Passed or Failed). 11 | 12 | The script then uses a SELECT statement to insert data into the #Groupings2 table, 13 | which includes the StepNumber, Status, and a calculated column Rnk. 14 | The Rnk column is calculated using the ROW_NUMBER() function with a window frame 15 | defined by the "PARTITION BY [Status] ORDER BY StepNumber" clause. 16 | This results in a unique ranking for each group of test cases with the same status. 17 | 18 | Finally, the script uses a SELECT statement with GROUP BY and aggregate functions to 19 | group the results in #Groupings2 by the Rnk column and the status. The query returns the minimum and 20 | maximum step numbers, the status, and the number of consecutive test cases in each group. 21 | The results are ordered by the minimum step number and status. 22 | 23 | **********************************************************************/ 24 | 25 | -------------- 26 | -------------- 27 | --Tables Used 28 | DROP TABLE IF EXISTS #Groupings; 29 | DROP TABLE IF EXISTS #Groupings2; 30 | GO 31 | 32 | -------------- 33 | -------------- 34 | --Groupings 35 | CREATE TABLE #Groupings 36 | ( 37 | StepNumber INTEGER PRIMARY KEY, 38 | TestCase VARCHAR(100), 39 | [Status] VARCHAR(100) 40 | ); 41 | GO 42 | 43 | INSERT INTO #Groupings VALUES 44 | (1,'Test Case 1','Passed'), 45 | (2,'Test Case 2','Passed'), 46 | (3,'Test Case 3','Passed'), 47 | (4,'Test Case 4','Passed'), 48 | (5,'Test Case 5','Failed'), 49 | (6,'Test Case 6','Failed'), 50 | (7,'Test Case 7','Failed'), 51 | (8,'Test Case 8','Failed'), 52 | (9,'Test Case 9','Failed'), 53 | (10,'Test Case 10','Passed'), 54 | (11,'Test Case 11','Passed'), 55 | (12,'Test Case 12','Passed'); 56 | GO 57 | 58 | -------------- 59 | -------------- 60 | --Create and insert into #Groupings2 61 | SELECT StepNumber, 62 | [Status], 63 | StepNumber - ROW_NUMBER() OVER (PARTITION BY [Status] ORDER BY StepNumber) AS Rnk 64 | INTO #Groupings2 65 | FROM #Groupings 66 | ORDER BY 2; 67 | GO 68 | 69 | -------------- 70 | -------------- 71 | --Display the results 72 | SELECT MIN(StepNumber) AS MinStepNumber, 73 | MAX(StepNumber) as MaxStepNumber, 74 | [Status], 75 | MAX(StepNumber) - MIN(StepNumber) + 1 AS ConsecutiveCount 76 | FROM #Groupings2 77 | GROUP BY Rnk, 78 | [Status] 79 | ORDER BY 1, 2; 80 | GO 81 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/12 Double Or Add 1 Recursion.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Double Or Add 1 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | The script creates a temporary table called #Numbers and populates it 9 | with a range of numbers specified by the variable @vTotalNumbers. 10 | The script uses a common table expression (CTE) to generate the numbers. 11 | 12 | The script then defines a second CTE called cte_Recursion, which performs 13 | the logic of either doubling or adding one to the previous number, depending 14 | on the condition (number * 2 < 100), using a CASE statement. The cte_recursion joins the cte_number table, 15 | and the number is incremented by one in the join clause. 16 | 17 | Finally, the script uses a SELECT statement to display the results of the cte_recursion. 18 | 19 | 20 | **********************************************************************/ 21 | 22 | ------------------------------- 23 | ------------------------------- 24 | --Tables Used 25 | DROP TABLE IF EXISTS #Numbers; 26 | GO 27 | 28 | ------------------------------- 29 | ------------------------------- 30 | --Declare variables 31 | --Set @vTotalNumbers to the desired score 32 | DECLARE @vTotalNumbers INTEGER = 100; 33 | 34 | ------------------------------- 35 | ------------------------------- 36 | --Create and populate a #Numbers table 37 | WITH cte_Number (Number) 38 | AS ( 39 | SELECT 1 AS Number 40 | UNION ALL 41 | SELECT Number + 1 42 | FROM cte_Number 43 | WHERE Number < @vTotalNumbers 44 | ) 45 | SELECT CAST(Number AS bigint) AS Number, 46 | (CASE Number WHEN 1 THEN 1 ELSE NULL END) AS Calculation 47 | INTO #Numbers 48 | FROM cte_Number 49 | OPTION (MAXRECURSION 101)--A value of 0 means no limit to the recursion level 50 | 51 | ------------------------------- 52 | ------------------------------- 53 | 54 | ;WITH cte_Numbers AS 55 | ( 56 | --Add a ranking function here if needed 57 | --Test data has StepNumber to rank/sort the records. 58 | SELECT number 59 | FROM #Numbers 60 | ), 61 | cte_Recursion AS 62 | ( 63 | SELECT Number, 64 | CASE WHEN Number = 1 THEN 1 ELSE Number * 2 END AS RunningSum 65 | FROM #Numbers 66 | WHERE Number = 1 67 | UNION ALL 68 | SELECT 69 | t.Number, 70 | CASE WHEN (RunningSum * 2) < 101 THEN (RunningSum * 2) ELSE RunningSum + 1 END AS RunningSum 71 | FROM cte_Recursion cte 72 | INNER JOIN 73 | cte_Numbers t ON t.Number = (cte.Number + 1) 74 | ) 75 | SELECT * 76 | FROM cte_Recursion 77 | WHERE RunningSum <= 100 78 | ORDER BY Number DESC; 79 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/13 Pascals Triangle Recursion.sql: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Pascal’s Triangle 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script solves Pascal's Triangle. 9 | https://en.wikipedia.org/wiki/Pascal%27s_triangle 10 | 11 | The position is determined by the user-specified variables @vRowNumber and @vPositionNumber, 12 | which correspond to the row and position of the value in the triangle, respectively. 13 | The script uses zero-based indexing, so the first row is row 0, and the first position is position 0. 14 | 15 | The script first checks if the value of the position is one. If the value is 1, it will return 1. 16 | If the value is not 1, the script uses common table expressions (CTEs) and the recursion to 17 | calculate the factorials of the specified row, position, and row minus position. 18 | Then the script calculates the final value of the position using the formula (Row! / (Position! * (Row-Position)!)). 19 | Finally, the script prints the final result of the calculated value of the position in Pascal's Triangle. 20 | 21 | 22 | Pascal's Triangle uses 0-based indexing. 23 | The first row is row 0. 24 | The first position is position 0. 25 | The factorial of 0! is 1. 26 | ------ 27 | 28 | Here are the first eight rows. 29 | 30 | 0 | 1 | 31 | 1 | 1 | 1 | 32 | 2 | 1 | 2 | 1 | 33 | 3 | 1 | 3 | 3 | 1 | 34 | 4 | 1 | 4 | 6 | 4 | 1 | 35 | 5 | 1 | 5 | 10 | 10 | 5 | 1 | 36 | 6 | 1 | 6 | 15 | 20 | 15 | 6 | 1 | 37 | 7 | 1 | 7 | 21 | 35 | 35 | 21 | 7 | 1 | 38 | ------------------------------------------- 39 | Pos. 0 | 1 | 2 | 3 | 4 | 5 | 6 | 7 | 40 | ------------------------------------------- 41 | 42 | 43 | **********************************************************************/ 44 | 45 | --Set your row and position 46 | --Remember to use 0-based indexing 47 | DECLARE @vRowNumber INTEGER = 4; 48 | DECLARE @vPositionNumber INTEGER = 3; 49 | 50 | ------------------------------- 51 | ------------------------------- 52 | --Variables to hold the Row, Position, and RowMinusPosition factorials 53 | --Factorial examples : 3! is 6, 4! is 24 54 | DECLARE @vRowFactorial INTEGER; 55 | DECLARE @vPositionFactorial INTEGER; 56 | DECLARE @vRowMinusPositionFactorial INTEGER; 57 | 58 | --@vPositionValue is calculated by @vRowFactorial / (@vPositionFactorial * @vRowMinusPositionFactorial) 59 | DECLARE @vPositionValue INTEGER; 60 | 61 | ------------------------------- 62 | ------------------------------- 63 | --Return 1 if (@vRowNumber - @vPositionNumber = 0) OR @vPositionNumber = 0 64 | --The factorial of 0! is 1 65 | IF (@vRowNumber - @vPositionNumber = 0) OR @vPositionNumber = 0 66 | BEGIN 67 | SET @vPositionValue = 1; 68 | RETURN;--------------------------------------------RETURN 69 | END; 70 | 71 | ------------------------------- 72 | ------------------------------- 73 | --Determine Row Factorial 74 | WITH cte_Factorial (Number, Factorial) 75 | AS ( 76 | SELECT 1, 77 | 1 78 | UNION ALL 79 | SELECT Number + 1, (Number + 1) * Factorial 80 | FROM cte_Factorial 81 | WHERE Number < @vRowNumber 82 | ) 83 | SELECT @vRowFactorial = Factorial 84 | FROM cte_Factorial; 85 | 86 | ------------------------------- 87 | ------------------------------- 88 | --Determine Position Factorial 89 | WITH cte_Factorial (Number, Factorial) 90 | AS ( 91 | SELECT 1, 92 | 1 93 | UNION ALL 94 | SELECT Number + 1, (Number + 1) * Factorial 95 | FROM cte_Factorial 96 | WHERE Number < @vPositionNumber 97 | ) 98 | SELECT @vPositionFactorial = Factorial 99 | FROM cte_Factorial; 100 | 101 | ------------------------------- 102 | ------------------------------- 103 | --Determine Row Minus Position Factorial 104 | WITH cte_Factorial (Number, Factorial) 105 | AS ( 106 | SELECT 1, 107 | 1 108 | UNION ALL 109 | SELECT Number + 1, (Number + 1) * Factorial 110 | FROM cte_Factorial 111 | WHERE Number < @vRowNumber - @vPositionNumber 112 | ) 113 | SELECT @vRowMinusPositionFactorial = Factorial 114 | FROM cte_Factorial; 115 | 116 | ------------------------------- 117 | ------------------------------- 118 | --Display the final results 119 | PRINT CONCAT('The value for Row ',@vRowNumber,' and Position ',@vPositionNumber,' is ',(@vRowFactorial / (@vPositionFactorial * @vRowMinusPositionFactorial))); 120 | GO 121 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Part II/23 Knight's Tour: -------------------------------------------------------------------------------- 1 | /********************************************************************* 2 | Scott Peters 3 | Knight's Tour 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/10/2024 6 | 7 | Microsoft SQL Server T-SQL 8 | 9 | This SQL statement solves a variation of the Knight's Tour problem. 10 | 11 | **********************************************************************/ 12 | 13 | DECLARE @CurrentPosition VARCHAR(2); 14 | SET @CurrentPosition = '4D'; -- Example starting position 15 | 16 | -- Mapping Letters to Numbers for calculation 17 | WITH cte_ChessBoard AS 18 | ( 19 | SELECT 'A' AS Letter, 1 AS Num 20 | UNION ALL SELECT 'B', 2 21 | UNION ALL SELECT 'C', 3 22 | UNION ALL SELECT 'D', 4 23 | UNION ALL SELECT 'E', 5 24 | UNION ALL SELECT 'F', 6 25 | UNION ALL SELECT 'G', 7 26 | UNION ALL SELECT 'H', 8 27 | ), 28 | cte_CurrentPosition AS 29 | ( 30 | SELECT CAST(SUBSTRING(@CurrentPosition, 1, 1) AS INTEGER) AS CurrentNumber, 31 | Num AS CurrentLetter 32 | FROM cte_ChessBoard a 33 | WHERE Letter = SUBSTRING(@CurrentPosition, 2, 1) 34 | ), 35 | cte_PossibleMoves AS 36 | ( 37 | SELECT CurrentNumber + i.NumberOffset AS NewNumber, 38 | CurrentLetter + i.LetterOffset AS NewLetter 39 | FROM cte_CurrentPosition, 40 | (VALUES (2, 1), (2, -1), (-2, 1), (-2, -1), (1, 2), (1, -2), 41 | (-1, 2), (-1, -2)) AS i(NumberOffset, LetterOffset) 42 | WHERE CurrentNumber + i.NumberOffset BETWEEN 1 AND 8 AND 43 | CurrentLetter + i.LetterOffset BETWEEN 1 AND 8 44 | ) 45 | SELECT CAST(NewNumber AS VARCHAR(1)) + b.Letter AS NewPosition 46 | FROM cte_PossibleMoves a INNER JOIN 47 | cte_Chessboard b ON a.NewLetter = b.Num; 48 | GO 49 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Associates Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Associates 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 07/03/2024 6 | Microsoft SQL Server T-SQL 7 | 8 | */---------------------------------------------------- 9 | 10 | --------------------- 11 | --------------------- 12 | DROP TABLE IF EXISTS #Associates; 13 | GO 14 | 15 | --------------------- 16 | --------------------- 17 | CREATE TABLE #Associates 18 | ( 19 | Associate1 VARCHAR(100), 20 | Associate2 VARCHAR(100), 21 | PRIMARY KEY (Associate1, Associate2) 22 | ); 23 | GO 24 | 25 | --------------------- 26 | --------------------- 27 | INSERT INTO #Associates (Associate1, Associate2) VALUES 28 | ('Anne','Betty'), 29 | ('Anne','Charles'), 30 | ('Betty','Dan'), 31 | ('Charles','Emma'), 32 | ('Francis','George'), 33 | ('George','Harriet'); 34 | GO 35 | 36 | --------------------- 37 | --------------------- 38 | WITH cte_Recursion AS 39 | ( 40 | SELECT Associate1, 41 | Associate2, 42 | 1 AS Depth 43 | FROM #Associates 44 | UNION ALL 45 | SELECT a.Associate1, 46 | b.Associate2, 47 | Depth + 1 AS Depth 48 | FROM #Associates a INNER JOIN 49 | cte_Recursion b ON a.Associate2 = b.Associate1 50 | ) 51 | SELECT * 52 | FROM cte_Recursion 53 | UNION ALL 54 | SELECT Associate1, 55 | Associate1, 56 | 0 AS Depth 57 | FROM #Associates; 58 | GO 59 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/DeGrouping Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | DeGrouping 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | */---------------------------------------------------- 9 | 10 | --------------------- 11 | --------------------- 12 | DROP TABLE IF EXISTS #Ungroup; 13 | GO 14 | 15 | --------------------- 16 | --------------------- 17 | CREATE TABLE #Ungroup 18 | ( 19 | ProductDescription VARCHAR(100) PRIMARY KEY, 20 | Quantity INTEGER NOT NULL 21 | ); 22 | GO 23 | 24 | --------------------- 25 | --------------------- 26 | INSERT INTO #Ungroup (ProductDescription, Quantity) VALUES 27 | ('Pencil',3),('Eraser',4),('Notebook',2); 28 | GO 29 | 30 | --------------------- 31 | --------------------- 32 | WITH cte_Recursion AS 33 | ( 34 | SELECT ProductDescription, Quantity 35 | FROM #Ungroup 36 | UNION ALL 37 | SELECT ProductDescription, Quantity-1 38 | FROM cte_Recursion 39 | WHERE Quantity >= 2 40 | ) 41 | SELECT ProductDescription,1 AS Quantity 42 | FROM cte_Recursion 43 | ORDER BY ProductDescription DESC; 44 | GO 45 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Double the Number Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Double the Number 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/07/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | Beginning at 1, this script uses a recursive statement to double the number for each record. 9 | 1, 2, 4, 8, 16, 32, etc..... 10 | 11 | */---------------------------------------------------- 12 | 13 | --------------------- 14 | --------------------- 15 | DROP TABLE IF EXISTS #Numbers; 16 | GO 17 | 18 | --------------------- 19 | --------------------- 20 | CREATE TABLE #Numbers 21 | ( 22 | Number INTEGER NOT NULL PRIMARY KEY 23 | ); 24 | 25 | INSERT INTO #Numbers VALUES (1),(2),(3),(4),(5); 26 | GO 27 | 28 | --------------------- 29 | --------------------- 30 | ;WITH cte_Numbers AS 31 | ( 32 | SELECT * 33 | FROM #Numbers 34 | ), 35 | cte_Recursion AS 36 | ( 37 | SELECT Number, 38 | CASE WHEN Number = 1 THEN 1 ELSE Number * 2 END AS RunningSum 39 | FROM #Numbers 40 | WHERE Number = 1 41 | UNION ALL 42 | SELECT 43 | t.Number, 44 | (RunningSum * 2) AS RunningSum 45 | FROM cte_Recursion cte 46 | INNER JOIN 47 | cte_Numbers t ON t.Number = (cte.Number + 1) 48 | ) 49 | SELECT * 50 | FROM cte_Recursion 51 | ORDER BY Number; 52 | GO 53 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Factorials Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Factorials 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to calculate factorials. 9 | 10 | */---------------------------------------------------- 11 | 12 | --------------------- 13 | --------------------- 14 | DECLARE @vTotalNumbers INTEGER = 10; 15 | 16 | --------------------- 17 | --------------------- 18 | WITH cte_Recursion (Number, Factorial) AS 19 | ( 20 | SELECT 1, 21 | 1 22 | UNION ALL 23 | SELECT Number + 1 AS Number, 24 | (Number + 1) * Factorial AS Factorial 25 | FROM cte_Recursion 26 | WHERE Number < @vTotalNumbers 27 | ) 28 | SELECT Number, 29 | Factorial 30 | FROM cte_Recursion 31 | OPTION (MAXRECURSION 0);--A value of 0 means no limit to the recursion level; 32 | 33 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Fibonacci Sequence Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Fibonacci Sequence 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to calculate Fibonacci numbers. 9 | 10 | */---------------------------------------------------- 11 | 12 | WITH cte_Recursion (PrevNumber, Number) AS 13 | ( 14 | SELECT 0, 1 15 | UNION ALL 16 | SELECT Number, PrevNumber + Number 17 | FROM cte_Recursion 18 | WHERE Number < 1000000000 19 | ) 20 | SELECT PrevNumber AS Fibonacci 21 | FROM cte_Recursion 22 | OPTION (MAXRECURSION 0); 23 | GO 24 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Floor and Ceiling Caps Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Floor and Ceiling Caps 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to display a running total where the sum 9 | cannot go higher than 10 or lower than 0. 10 | 11 | */---------------------------------------------------- 12 | 13 | 14 | DROP TABLE IF EXISTS #Numbers; 15 | GO 16 | 17 | CREATE TABLE #Numbers 18 | ( 19 | Id INTEGER, 20 | StepNumber INTEGER, 21 | [Count] INTEGER 22 | ); 23 | GO 24 | 25 | INSERT INTO #Numbers VALUES 26 | (1,1,1) 27 | ,(1,2,-2) 28 | ,(1,3,-1) 29 | ,(1,4,12) 30 | ,(1,5,-2) 31 | ,(2,1,7) 32 | ,(2,2,-3); 33 | GO 34 | 35 | WITH cte_Numbers AS 36 | ( 37 | SELECT * 38 | FROM #Numbers 39 | ), 40 | cte_Recursion AS 41 | ( 42 | SELECT Id, 43 | [Count], 44 | [Count] as RunningSum, 45 | CASE WHEN [Count] < 0 THEN 0 46 | WHEN [Count] > 10 THEN 10 47 | ELSE [Count] 48 | END AS RunningSumFloorCap, 49 | StepNumber 50 | FROM #Numbers 51 | WHERE StepNumber = 1 52 | UNION ALL 53 | SELECT cte.ID, 54 | t.[Count], 55 | t.[Count] + cte.[Count], 56 | (CASE WHEN t.[Count] + cte.RunningSumFloorCap < 0 THEN 0 57 | WHEN t.[Count] + cte.RunningSumFloorCap > 10 THEN 10 58 | ELSE t.[Count] + cte.RunningSumFloorCap 59 | END) AS RunningSumFloorCap, 60 | t.StepNumber 61 | FROM cte_Recursion cte 62 | INNER JOIN 63 | cte_Numbers t ON t.StepNumber = (cte.StepNumber + 1) AND t.ID = cte.ID 64 | ) 65 | SELECT * 66 | FROM cte_Recursion 67 | ORDER BY ID, 68 | StepNumber; 69 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Group Concatenation Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Group Concatenation 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/07/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to concatenate the values of string expressions and places separator values between them. 9 | Note this provides the same functionality as the STRING_AGG function. 10 | 11 | */---------------------------------------------------- 12 | 13 | ------------------------------- 14 | ------------------------------- 15 | DROP TABLE IF EXISTS #Example; 16 | GO 17 | 18 | ------------------------------- 19 | ------------------------------- 20 | CREATE TABLE #Example 21 | ( 22 | SequenceNumber INTEGER PRIMARY KEY, 23 | String VARCHAR(100) 24 | ); 25 | GO 26 | 27 | INSERT INTO #Example VALUES 28 | (1,'Hello'), 29 | (2,'World!'); 30 | GO 31 | 32 | ------------------------------- 33 | ------------------------------- 34 | WITH 35 | cte_Recursion(String2,Depth) AS 36 | ( 37 | SELECT CAST('' AS NVARCHAR(MAX)), 38 | CAST(MAX(SequenceNumber) AS INTEGER) 39 | FROM #Example 40 | UNION ALL 41 | SELECT e.String + ' ' + r.String2, r.Depth - 1 42 | FROM cte_Recursion r INNER JOIN 43 | #Example e ON r.Depth = e.SequenceNumber 44 | ) 45 | SELECT String2 46 | FROM cte_Recursion 47 | WHERE Depth = 0; 48 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Growing Numbers Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Growing Numbers 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to create a growing number list. 9 | Given the input (1,2,3), this script will produce the following: 10 | 1 11 | 1,2 12 | 1,2,3 13 | 14 | */---------------------------------------------------- 15 | 16 | --------------------- 17 | --------------------- 18 | --Tables used 19 | DROP TABLE IF EXISTS #Numbers; 20 | DROP TABLE IF EXISTS #Permutations; 21 | GO 22 | 23 | --------------------- 24 | --------------------- 25 | CREATE TABLE #Numbers 26 | ( 27 | Number INTEGER NOT NULL 28 | ); 29 | GO 30 | 31 | INSERT INTO #Numbers (Number) VALUES 32 | (1),(2),(3),(4),(5); --Passes 33 | --(6),(7),(8),(9),(10); --Passes 34 | --(5),(7),(8),(9),(10); --Does Not Pass (Gap between 5 and 7) 35 | --(7),(8),(9),(10),(11); --Does Not Pass (Two numbers greater than 10) 36 | --(10),(11),(12); --Does Not Pass (Lowest number is not a single digit and the set contains two numbers greater than 10) 37 | GO 38 | 39 | --------------------- 40 | --------------------- 41 | --Declare and set variables 42 | DECLARE @vTotalNumbers INTEGER = (SELECT COUNT(*) FROM #Numbers); 43 | 44 | --------------------- 45 | --------------------- 46 | --Create the #Permutations table using recursion 47 | WITH cte_Recursion (Permutation, Id, Depth) 48 | AS 49 | ( 50 | SELECT CAST(Number AS VARCHAR(MAX)) AS Permutation, 51 | CAST(CONCAT(Number,'') AS VARCHAR(MAX)) AS Id, 52 | 1 AS Depth 53 | FROM #Numbers 54 | UNION ALL 55 | SELECT CONCAT(a.Permutation,b.Number), 56 | CONCAT(a.Id,b.Number), 57 | a.Depth + 1 58 | FROM cte_Recursion a, 59 | #Numbers b 60 | WHERE a.Depth < @vTotalNumbers AND 61 | CAST(RIGHT(a.Id,1) AS INTEGER) + 1 = b.Number 62 | ) 63 | SELECT Permutation 64 | INTO #Permutations 65 | FROM cte_Recursion; 66 | 67 | --------------------- 68 | --------------------- 69 | --Display the results 70 | SELECT * 71 | FROM #Permutations 72 | WHERE LEFT(Permutation,1) = (SELECT MIN(Number) FROM #Numbers); 73 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Managers and Employees Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Managers and Employees 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to display the depth given a managers and employees table. 9 | 10 | */---------------------------------------------------- 11 | 12 | --------------------- 13 | --------------------- 14 | DROP TABLE IF EXISTS #Employees; 15 | GO 16 | 17 | --------------------- 18 | --------------------- 19 | CREATE TABLE #Employees 20 | ( 21 | EmployeeID INTEGER PRIMARY KEY, 22 | ManagerID INTEGER, 23 | JobTitle VARCHAR(100), 24 | Salary INTEGER 25 | ); 26 | GO 27 | 28 | --------------------- 29 | --------------------- 30 | INSERT INTO #Employees VALUES 31 | (1001,NULL,'President',185000),(2002,1001,'Director',120000), 32 | (3003,1001,'Office Manager',97000),(4004,2002,'Engineer',110000), 33 | (5005,2002,'Engineer',142000),(6006,2002,'Engineer',160000); 34 | GO 35 | 36 | --------------------- 37 | --------------------- 38 | WITH cte_Recursion AS 39 | ( 40 | SELECT EmployeeID, 41 | ManagerID, 42 | JobTitle, 43 | Salary, 44 | 0 AS Depth 45 | FROM #Employees a 46 | WHERE ManagerID IS NULL 47 | UNION ALL 48 | SELECT b.EmployeeID, 49 | b.ManagerID, 50 | b.JobTitle, 51 | b.Salary, 52 | a.Depth + 1 AS Depth 53 | FROM cte_Recursion a INNER JOIN 54 | #Employees b ON a.EmployeeID = b.ManagerID 55 | ) 56 | SELECT EmployeeID, ManagerID, JobTitle, Salary, Depth 57 | FROM cte_Recursion; 58 | GO 59 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Mandelbrot Set Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Mandelbrot Set 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 07/03/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to create a Mandelbrot set. 9 | 10 | See the link below for the original author of the SQL code. 11 | https://thedailywtf.com/articles/stupid-coding-tricks-the-tsql-madlebrot 12 | 13 | */---------------------------------------------------- 14 | 15 | WITH 16 | XGEN(X, IX) AS ( -- X DIM GENERATOR 17 | SELECT CAST(-2.2 AS FLOAT) AS X, 0 AS IX UNION ALL 18 | SELECT CAST(X + 0.031 AS FLOAT) AS X, IX + 1 AS IX 19 | FROM XGEN 20 | WHERE IX < 100 21 | ), 22 | YGEN(Y, IY) AS ( -- Y DIM GENERATOR 23 | SELECT CAST(-1.5 AS FLOAT) AS Y, 0 AS IY UNION ALL 24 | SELECT CAST(Y + 0.031 AS FLOAT) AS Y, IY + 1 AS IY 25 | FROM YGEN 26 | WHERE IY < 100 27 | ), 28 | Z(IX, IY, CX, CY, X, Y, I) AS ( -- Z POINT ITERATOR 29 | SELECT IX, IY, X, Y, X, Y, 0 30 | FROM XGEN, YGEN 31 | UNION ALL 32 | SELECT IX, IY, CX, CY, X * X - Y * Y + CX AS X, Y * X * 2 + CY, I + 1 33 | FROM Z 34 | WHERE X * X + Y * Y < 16 35 | AND I < 100 36 | ) 37 | SELECT REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( 38 | REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( 39 | REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(REPLACE( 40 | (X0+X1+X2+X3+X4+X5+X6+X7+X8+X9+X10+X11+X12+X13+X14+X15+X16+X17+X18+X19+ 41 | X20+X21+X22+X23+X24+X25+X26+X27+X28+X29+X30+X31+X32+X33+X34+X35+X36+X37+X38+X39+ 42 | X40+X41+X42+X43+X44+X45+X46+X47+X48+X49+X50+X51+X52+X53+X54+X55+X56+X57+X58+X59+ 43 | X60+X61+X62+X63+X64+X65+X66+X67+X68+X69+X70+X71+X72+X73+X74+X75+X76+X77+X78+X79+ 44 | X80+X81+X82+X83+X84+X85+X86+X87+X88+X89+X90+X91+X92+X93+X94+X95+X96+X97+X98+X99), 45 | 'A',' '), 'B','.'), 'C',','), 'D',','), 'E',','), 'F','-'), 'G','-'), 46 | 'H','-'), 'I','-'), 'J','-'), 'K','+'), 'L','+'), 'M','+'), 'N','+'), 47 | 'O','%'), 'P','%'), 'Q','%'), 'R','%'), 'S','@'), 'T','@'), 'U','@'), 48 | 'V','@'), 'W','#'), 'X','#'), 'Y','#'), 'Z',' ') 49 | FROM ( 50 | SELECT 'X' + CAST(IX AS VARCHAR) AS IX, 51 | IY, SUBSTRING('ABCDEFGHIJKLMNOPQRSTUVWXYZ', ISNULL(NULLIF(I, 0), 1), 1) AS I 52 | FROM Z) ZT 53 | PIVOT ( 54 | MAX(I) FOR IX IN ( 55 | X0,X1,X2,X3,X4,X5,X6,X7,X8,X9,X10,X11,X12,X13,X14,X15,X16,X17,X18,X19, 56 | X20,X21,X22,X23,X24,X25,X26,X27,X28,X29,X30,X31,X32,X33,X34,X35,X36,X37,X38,X39, 57 | X40,X41,X42,X43,X44,X45,X46,X47,X48,X49,X50,X51,X52,X53,X54,X55,X56,X57,X58,X59, 58 | X60,X61,X62,X63,X64,X65,X66,X67,X68,X69,X70,X71,X72,X73,X74,X75,X76,X77,X78,X79, 59 | X80,X81,X82,X83,X84,X85,X86,X87,X88,X89,X90,X91,X92,X93,X94,X95,X96,X97,X98,X99) 60 | ) AS PZT 61 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Markov Chain Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Markov Chains 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 02/07/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to solve a Markov Chain. 9 | https://en.wikipedia.org/wiki/Markov_chain 10 | 11 | In Probability Land, on a sunny day, there is an equal probability of the next day being sunny or rainy. 12 | On a rainy day, there is a 70% chance it will rain the next day and a 30% chance it will be sunny the next day. 13 | 14 | On average, how many rainy days are there in Probability Land? 15 | 16 | */---------------------------------------------------- 17 | 18 | ------------------------------- 19 | ------------------------------- 20 | 21 | DROP TABLE IF EXISTS #Probabilities; 22 | DROP TABLE IF EXISTS #Numbers; 23 | DROP TABLE IF EXISTS #RandomNumbers; 24 | DROP TABLE IF EXISTS #ProbabilitiesFinal; 25 | GO 26 | 27 | ------------------------------- 28 | ------------------------------- 29 | CREATE TABLE #Probabilities 30 | ( 31 | CurrentState INTEGER NOT NULL, 32 | FutureState INTEGER NOT NULL, 33 | Probability INTEGER NOT NULL, 34 | ); 35 | GO 36 | 37 | --1 is Rainy, 2 is Sunny 38 | INSERT INTO #Probabilities (CurrentState, FutureState, Probability) VALUES 39 | (1,1,1),(1,1,2),(1,1,3),(1,1,4),(1,1,5),(1,1,6),(1,1,7),(1,2,8),(1,2,9),(1,2,10), 40 | (2,2,1),(2,2,2),(2,2,3),(2,2,4),(2,2,5),(2,1,6),(2,1,7),(2,1,8),(2,1,9),(2,1,10); 41 | GO 42 | 43 | ------------------------------- 44 | ------------------------------- 45 | DECLARE @vTotalNumbers INTEGER = 10000; 46 | ------------------------------- 47 | ------------------------------- 48 | WITH cte_Recursion (Number) 49 | AS ( 50 | SELECT 1 AS Number 51 | UNION ALL 52 | SELECT Number + 1 53 | FROM cte_Recursion 54 | WHERE Number < @vTotalNumbers 55 | ) 56 | SELECT Number AS StepNumber 57 | INTO #Numbers 58 | FROM cte_Recursion 59 | OPTION (MAXRECURSION 0); 60 | 61 | ------------------------------- 62 | ------------------------------- 63 | SELECT StepNumber, 64 | CAST(NULL AS INTEGER) AS CurrentState, 65 | ABS(CHECKSUM(NEWID()) % 10) + 1 AS Probability 66 | INTO #RandomNumbers 67 | FROM #Numbers; 68 | GO 69 | 70 | --Seed the first record in the #RandomNumbers table 71 | --I'm arbitrarily setting this to 1 (Rain). 72 | UPDATE #RandomNumbers 73 | SET CurrentState = 1 74 | WHERE StepNumber = 1; 75 | GO 76 | 77 | ------------------------------- 78 | ------------------------------- 79 | WITH cte_Recursion AS 80 | ( 81 | SELECT StepNumber 82 | ,Probability 83 | ,CurrentState 84 | FROM #RandomNumbers a WHERE StepNumber = 1 85 | UNION ALL 86 | SELECT n.StepNumber 87 | ,n.Probability 88 | ,CAST(p.FutureState AS INTEGER) AS CurrentState 89 | FROM cte_Recursion cte 90 | INNER JOIN 91 | #RandomNumbers n ON (cte.StepNumber + 1) = n.StepNumber 92 | INNER JOIN 93 | #Probabilities p ON cte.Probability = p.Probability AND cte.CurrentState = p.CurrentState 94 | ) 95 | SELECT StepNumber 96 | ,CurrentState 97 | ,(CASE CurrentState WHEN 1 THEN 'Rainy' WHEN 2 THEN 'Sunny' END) AS [Description] 98 | ,Probability 99 | INTO #ProbabilitiesFinal 100 | FROM cte_Recursion 101 | ORDER BY StepNumber 102 | OPTION (MAXRECURSION 0); 103 | GO 104 | 105 | ------------------------------- 106 | ------------------------------- 107 | SELECT [Description], 108 | COUNT(*) AS [Count] 109 | FROM #ProbabilitiesFinal 110 | GROUP BY [Description] 111 | ORDER BY 1; 112 | GO 113 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Numbers Table Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Numbers Table 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to build a numbers table. 9 | Set the start and end numbers via the variables @vStartNumber and @vEndNumber. 10 | 11 | */---------------------------------------------------- 12 | 13 | --------------------- 14 | --------------------- 15 | DECLARE @vStartNumber INTEGER = -8; 16 | DECLARE @vEndNumber INTEGER = 10; 17 | 18 | --------------------- 19 | --------------------- 20 | WITH cte_Recursion (Number) 21 | AS 22 | ( 23 | SELECT @vStartNumber AS Number 24 | UNION ALL 25 | SELECT Number + 1 26 | FROM cte_Recursion 27 | WHERE Number < @vEndNumber 28 | ) 29 | SELECT Number 30 | FROM cte_Recursion 31 | OPTION (MAXRECURSION 100); 32 | GO 33 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Permutations Bit Mask Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Permutations (using Bit Mask) 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to display all permutations for the numbers 1 through n. 9 | 10 | */---------------------------------------------------- 11 | 12 | --------------------- 13 | --------------------- 14 | --Tables used 15 | DROP TABLE IF EXISTS #Numbers; 16 | GO 17 | 18 | --------------------- 19 | --------------------- 20 | --Declare and set variables 21 | DECLARE @vTotalNumbers BIGINT = 3; 22 | 23 | --------------------- 24 | --------------------- 25 | --Create a #Numbers table using recursion 26 | WITH cte_Recursion (Number) AS 27 | ( 28 | SELECT 1 AS Number 29 | UNION ALL 30 | SELECT Number + 1 31 | FROM cte_Recursion 32 | WHERE Number < @vTotalNumbers 33 | ) 34 | SELECT 35 | Number 36 | INTO #Numbers 37 | FROM cte_Recursion 38 | OPTION (MAXRECURSION 0); 39 | 40 | --------------------- 41 | --------------------- 42 | WITH cte_Numbers AS 43 | ( 44 | SELECT CAST(Number AS VARCHAR(MAX)) AS Number 45 | FROM #Numbers 46 | ), 47 | cte_Bitmasks AS 48 | ( 49 | SELECT 50 | Number, 51 | CAST(POWER(2, ROW_Number() OVER (ORDER BY Number) - 1) AS INT) AS Bitmask 52 | FROM cte_Numbers 53 | ), 54 | cte_Recursion AS 55 | ( 56 | SELECT Number AS Permutation, 57 | Bitmask 58 | FROM cte_Bitmasks 59 | UNION ALL 60 | SELECT p.Permutation + ',' + b.Number, 61 | p.Bitmask ^ b.Bitmask 62 | FROM cte_Recursion p INNER JOIN 63 | cte_Bitmasks b ON p.Bitmask ^ b.Bitmask > p.Bitmask 64 | ) 65 | SELECT ROW_NUMBER() OVER (ORDER BY GETDATE()) AS Id, 66 | Permutation 67 | FROM cte_Recursion 68 | WHERE Bitmask = POWER(2, (SELECT COUNT(*) FROM cte_Numbers)) - 1; 69 | GO 70 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Permutations Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Permutations 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | Displays all permutations for the numbers 1 through n. 9 | 10 | */---------------------------------------------------- 11 | 12 | --------------------- 13 | --------------------- 14 | DROP TABLE IF EXISTS #Numbers; 15 | GO 16 | 17 | --------------------- 18 | --------------------- 19 | DECLARE @vTotalNumbers INTEGER = 3; 20 | 21 | --------------------- 22 | --------------------- 23 | WITH cte_Numbers (Number) 24 | AS ( 25 | SELECT 1 AS Number 26 | UNION ALL 27 | SELECT Number + 1 28 | FROM cte_Numbers 29 | WHERE Number < @vTotalNumbers 30 | ) 31 | SELECT 32 | Number 33 | INTO #Numbers 34 | FROM cte_Numbers 35 | OPTION (MAXRECURSION 0); 36 | 37 | --------------------- 38 | --------------------- 39 | WITH cte_Recursion (Permutation, Id, Depth) 40 | AS 41 | ( 42 | SELECT CAST(Number AS VARCHAR(MAX)), 43 | CAST(CONCAT(Number,';') AS VARCHAR(MAX)), 44 | 1 AS Depth 45 | FROM #Numbers 46 | UNION ALL 47 | SELECT CONCAT(a.Permutation,',',b.Number), 48 | CONCAT(a.Id,b.Number,';'), 49 | a.Depth + 1 50 | FROM cte_Recursion a, 51 | #Numbers b 52 | WHERE a.Depth < @vTotalNumbers AND 53 | a.Id NOT LIKE CONCAT('%',b.Number,';%') 54 | ) 55 | SELECT Permutation 56 | FROM cte_Recursion; 57 | GO 58 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/String Split Each Character Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | String Split Each Character 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to split a string into rows of substrings for each character in the string. 9 | 10 | */---------------------------------------------------- 11 | 12 | ------------------------------- 13 | ------------------------------- 14 | DROP TABLE IF EXISTS #Example; 15 | GO 16 | 17 | ------------------------------- 18 | ------------------------------- 19 | CREATE TABLE #Example 20 | ( 21 | Id INTEGER IDENTITY(1,1) PRIMARY KEY, 22 | String VARCHAR(30) NOT NULL 23 | ); 24 | GO 25 | 26 | INSERT INTO #Example VALUES('123456789'),('abcdefghi'); 27 | GO 28 | 29 | ------------------------------- 30 | ------------------------------- 31 | ;WITH cte_Recursion AS 32 | ( 33 | SELECT Id, 34 | String, 35 | STUFF(String,1,1,'') AS String_Stuff, 36 | LEFT(String,1) AS String_Left 37 | FROM #Example 38 | UNION ALL 39 | SELECT Id, 40 | String, 41 | STUFF(String_Stuff,1,1,'') String_Stuff, 42 | LEFT(String_Stuff,1) AS String_Left 43 | FROM cte_Recursion 44 | WHERE LEN(String_Stuff) > 0 45 | ) 46 | SELECT 47 | Id, 48 | ROW_NUMBER() OVER (PARTITION BY Id ORDER BY GETDATE()) AS RowNumber, 49 | String, 50 | String_Left AS String_Value, 51 | ISNUMERIC(String_Left) AS [IsNumeric] 52 | FROM cte_Recursion 53 | ORDER BY 1,2; 54 | GO 55 | 56 | ---------------------------------------------------------------- 57 | --String splitting can also be solved by using a Numbers table-- 58 | ---------------------------------------------------------------- 59 | 60 | DROP TABLE IF EXISTS #Numbers; 61 | GO 62 | 63 | CREATE TABLE #Numbers 64 | ( 65 | MyInteger INTEGER NOT NULL PRIMARY KEY 66 | ); 67 | GO 68 | 69 | INSERT INTO #Numbers VALUES(1),(2),(3),(4),(5); 70 | GO 71 | 72 | WITH cte_Length AS 73 | ( 74 | SELECT 1 AS Id, 'Super' AS Word, LEN('Super') AS WordLength 75 | UNION 76 | SELECT 2, 'Fly', LEN('fly') 77 | ) 78 | SELECT *, SUBSTRING(a.Word, b.MyInteger, 1) AS Character 79 | FROM cte_Length a LEFT OUTER JOIN 80 | #Numbers b ON b.MyInteger <= a.WordLength; 81 | GO 82 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/String Split Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | String Split 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to split a string into rows of substrings based on a specified separator character 9 | This script provides the same functionality as the STRING_SPLIT function. 10 | 11 | */---------------------------------------------------- 12 | 13 | ------------------------------- 14 | ------------------------------- 15 | DROP TABLE IF EXISTS #Example; 16 | GO 17 | 18 | ------------------------------- 19 | ------------------------------- 20 | SELECT * 21 | INTO #Example 22 | FROM (VALUES(1,'George Washington'),(2,'Thomas Jefferson')) n(Id,String); 23 | GO 24 | 25 | ------------------------------- 26 | ------------------------------- 27 | ;WITH cte_String AS 28 | ( 29 | SELECT Id, 30 | CAST(String AS VARCHAR(200)) AS String 31 | FROM #Example 32 | ), 33 | cte_Recursion AS 34 | ( 35 | SELECT Id, 36 | String, 37 | 1 AS Starts, 38 | CHARINDEX(' ', String) AS Position 39 | FROM cte_String 40 | UNION ALL 41 | SELECT Id, 42 | String, 43 | Position + 1, 44 | CHARINDEX(' ', String, Position + 1) 45 | FROM cte_Recursion 46 | WHERE Position > 0 47 | ) 48 | SELECT ROW_NUMBER() OVER (PARTITION BY Id ORDER BY Starts) AS RowNumber, 49 | String, 50 | SUBSTRING(String, Starts, CASE WHEN Position > 0 THEN Position - Starts ELSE LEN(String) END) Word 51 | FROM cte_Recursion 52 | ORDER BY Id, Starts; 53 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Sudoku Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Sudoku 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to solve a Sudoku puzzle. 9 | 10 | */---------------------------------------------------- 11 | 12 | ------------------------------- 13 | ------------------------------- 14 | DECLARE @vBoard VARCHAR(81) = '86....3...2...1..7....74...27.9..1...8.....7...1..7.95...56....4..1...5...3....81'; 15 | 16 | ------------------------------- 17 | ------------------------------- 18 | WITH cte_Recursion(Sudoku,IndexValue) AS 19 | ( 20 | SELECT Sudoku, 21 | CHARINDEX('.',Sudoku) AS IndexValue 22 | FROM (VALUES(@vBoard)) AS Input(Sudoku) 23 | UNION ALL 24 | SELECT CONVERT(VARCHAR(81),CONCAT(SUBSTRING(Sudoku,1,IndexValue-1),myRecursion,SUBSTRING(Sudoku,IndexValue+1,81))) AS Sudoku, 25 | CHARINDEX('.',CONCAT(SUBSTRING(Sudoku,1,IndexValue-1),myRecursion,SUBSTRING(Sudoku,IndexValue+1,81))) AS IndexValue 26 | FROM cte_Recursion INNER JOIN (VALUES('1'),('2'),('3'),('4'),('5'),('6'),('7'),('8'),('9') 27 | ) AS Digits(myRecursion) ON NOT EXISTS ( 28 | SELECT 1 29 | FROM (VALUES(1),(2),(3),(4),(5),(6),(7),(8),(9)) AS Positions(lp) 30 | WHERE myRecursion = SUBSTRING(Sudoku, ((IndexValue-1)/9)*9 + lp, 1) OR 31 | myRecursion = SUBSTRING(Sudoku, ((IndexValue-1)%9) + (lp-1)*9 + 1, 1) OR 32 | myRecursion = SUBSTRING(Sudoku, (((IndexValue-1)/3) % 3) * 3 + ((IndexValue-1)/27) * 27 + lp + ((lp-1) / 3) * 6, 1) 33 | ) 34 | WHERE IndexValue > 0 35 | ) 36 | SELECT 'One long line:' AS Type, Sudoku FROM cte_Recursion WHERE IndexValue = 0 UNION 37 | SELECT '1' AS Line, SUBSTRING(Sudoku,1,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 38 | SELECT '2' AS Type, SUBSTRING(Sudoku,10,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 39 | SELECT '3' AS Type, SUBSTRING(Sudoku,19,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 40 | SELECT '4' AS Type, SUBSTRING(Sudoku,29,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 41 | SELECT '5' AS Type, SUBSTRING(Sudoku,37,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 42 | SELECT '6' AS Type, SUBSTRING(Sudoku,46,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 43 | SELECT '7' AS Type, SUBSTRING(Sudoku,55,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 44 | SELECT '8' AS Type, SUBSTRING(Sudoku,64,9) AS Line FROM cte_Recursion WHERE IndexValue = 0 UNION 45 | SELECT '9' AS Type, SUBSTRING(Sudoku,73,9) AS Line FROM cte_Recursion WHERE IndexValue = 0; 46 | GO 47 | 48 | /* 49 | Here is the answer: 50 | 51 | 867295314 52 | 924381567 53 | 135674829 54 | 276953148 55 | 589416273 56 | 341827695 57 | 718569432 58 | 492138756 59 | 653742981 60 | */ 61 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/Recursion Examples/Traveling Salesman Recursion.sql: -------------------------------------------------------------------------------- 1 | /*---------------------------------------------------- 2 | Scott Peters 3 | Traveling Salesman 4 | https://advancedsqlpuzzles.com 5 | Last Updated: 01/13/2023 6 | Microsoft SQL Server T-SQL 7 | 8 | This script uses recursion to solve the Traveling Salesman Problem 9 | https://en.wikipedia.org/wiki/Travelling_salesman_problem 10 | 11 | */---------------------------------------------------- 12 | 13 | SET NOCOUNT ON; 14 | DROP TABLE IF EXISTS #TravelingSalesman; 15 | DROP TABLE IF EXISTS #Routes; 16 | GO 17 | 18 | ---------------------- 19 | ---------------------- 20 | ---------------------- 21 | 22 | CREATE TABLE #Routes 23 | ( 24 | FromNode VARCHAR(30) NOT NULL, 25 | ToNode VARCHAR(30) NOT NULL, 26 | Cost MONEY NOT NULL, 27 | PRIMARY KEY (FromNode, ToNode) 28 | ); 29 | GO 30 | 31 | INSERT #Routes (FromNode, ToNode, Cost) 32 | OUTPUT INSERTED.ToNode AS FromNode, 33 | INSERTED.FromNode AS ToNode, 34 | INSERTED.Cost 35 | INTO #Routes (FromNode, ToNode, Cost) 36 | VALUES 37 | ('Austin','Dallas',100), 38 | ('Dallas','Memphis',200), 39 | ('Memphis','Des Moines',300), 40 | ('Dallas','Des Moines',400); 41 | GO 42 | 43 | WITH cteMap(Nodes, LastNode, NodeMap, Cost) 44 | AS ( 45 | SELECT 2 AS Nodes, 46 | ToNode, 47 | CAST('\' + FromNode + '\' + ToNode + '\' AS VARCHAR(MAX)) AS NodeMap, 48 | Cost 49 | FROM #Routes 50 | WHERE FromNode = 'Austin' 51 | UNION ALL 52 | SELECT m.Nodes + 1 AS Nodes, 53 | r.ToNode AS LastNode, 54 | CAST(m.NodeMap + r.ToNode + '\' AS VARCHAR(MAX)) AS NodeMap, 55 | m.Cost + r.Cost AS Cost 56 | FROM cteMap AS m INNER JOIN 57 | #Routes AS r ON r.FromNode = m.LastNode 58 | WHERE m.NodeMap NOT LIKE '\%' + r.ToNode + '%\' 59 | ) 60 | SELECT NodeMap, Cost 61 | INTO #TravelingSalesman 62 | FROM cteMap 63 | OPTION (MAXRECURSION 0); 64 | GO 65 | -------------------------------------------------------------------------------- /Advanced SQL Puzzles/readme.md: -------------------------------------------------------------------------------- 1 | # Advanced SQL Puzzles 2 | 3 | This directory contains my collection of SQL puzzles. I hope you enjoy these puzzles as much as I have enjoyed creating them! 4 | 5 | To get started, download the `Advanced SQL Puzzles.pdf`. 6 | 7 | :keyboard:      The solutions provided are written in Microsoft SQL Server T-SQL, but you can easily modify them to fit your flavor of SQL. 8 | 9 | :question:      If you have any questions, please feel free to create a GitHub discussion. I am always happy to help out and explain different solutions. 10 | 11 | ## About 12 | 13 | As my list of puzzles continues to grow, I have decided to combine the puzzles into one single PDF document broken down into two different sections. 14 | 15 | * In the first section, I have 64 of the most difficult puzzles I could create, randomly organized and in no specific order. These are primarily set-based puzzles, interspersed with a small number of puzzles that require knowledge of constraints, specific data types, cursors, loops, etc... 16 | 17 | * In the second set of puzzles, I have collected all the puzzles related to permutations, combinations, and sequences. Solving these puzzles will require a deeper knowledge of your SQL thinking, focusing on such constructs as using recursion or sequence objects to reach the desired output. 18 | 19 | ## Getting Started 20 | 21 | To get started, download the `Advanced SQL Puzzles.pdf`. 22 | 23 | * Solutions are provided in the `Advanced SQL Puzzles Solutions.sql` script 24 | * If you want the `CREATE TABLE` and `INSERT` statements without the solutions, see the script `Advanced SQL Puzzles DDL.sql`. 25 | * Solutions for the second set of puzzles are located in the directory `Part II`. 26 | * I also keep my collection of SQL statements using recursion in the directory `Recursion Examples`. Here you can find out how to solve [Markov chains](https://en.wikipedia.org/wiki/Markov_chain), solve the [Traveling Salesman](https://en.wikipedia.org/wiki/Travelling_salesman_problem) problem, calculate floor and ceiling caps, or find a solution to a [Sudoku](https://en.wikipedia.org/wiki/Sudoku) puzzle. 27 | 28 | 29 | ---------------- 30 | 31 | :mailbox:      If you find any inaccuracies, misspellings, bugs, dead links, etc... please report an issue! No detail is too small, and I appreciate all the help. 32 | 33 | :smile:      Happy coding! 34 | 35 | I hope you find this repository to be useful and informative, and I welcome any new puzzles or tips and tricks you may have. I also have a WordPress site where you can find my data analytics projects, Python puzzles, and blog. 36 | 37 | https://advancedsqlpuzzles.com 38 | -------------------------------------------------------------------------------- /Database Articles/Advanced SQL Joins/Sample Data.md: -------------------------------------------------------------------------------- 1 | # Sample Data 2 | 3 |       For the following examples you will need to understand the behavior of NULL markers. I’ve provided some rather simple tables with minimal records. I've also included a few NULL markers to understand how the various joins treat this particular case. 4 | 5 | **Table A** 6 | | ID | Fruit | Quantity | 7 | |----|---------|----------| 8 | | 1 | Apple | 17 | 9 | | 2 | Peach | 20 | 10 | | 3 | Mango | 11 | 11 | | 4 | \ | 5 | 12 | 13 | **Table B** 14 | | ID | Fruit | Quantity | 15 | |----|---------|----------| 16 | | 1 | Apple | 17 | 17 | | 2 | Peach | 25 | 18 | | 3 | Kiwi | 20 | 19 | | 4 | \ | \ | 20 | 21 |       In some statements, the example data may not be sufficient. Feel free to add your own data and experiment with the outcomes. 22 | 23 | ```sql 24 | ------------------------ 25 | --Create Sample Tables-- 26 | ------------------------ 27 | 28 | DROP TABLE IF EXISTS ##TableA; 29 | DROP TABLE IF EXISTS ##TableB; 30 | 31 | CREATE TABLE ##TableA 32 | ( 33 | ID INTEGER NOT NULL PRIMARY KEY, 34 | Fruit VARCHAR(10) NULL UNIQUE, 35 | Quantity INTEGER 36 | ); 37 | 38 | CREATE TABLE ##TableB 39 | ( 40 | ID INTEGER NOT NULL PRIMARY KEY, 41 | Fruit VARCHAR(10) NULL UNIQUE, 42 | Quantity INTEGER 43 | ); 44 | 45 | INSERT INTO ##TableA VALUES (1,'Apple',17); 46 | INSERT INTO ##TableA VALUES (2,'Peach',20); 47 | INSERT INTO ##TableA VALUES (3,'Mango',11); 48 | INSERT INTO ##TableA VALUES (4,NULL,5); 49 | 50 | INSERT INTO ##TableB VALUES (1,'Apple',17); 51 | INSERT INTO ##TableB VALUES (2,'Peach',25); 52 | INSERT INTO ##TableB VALUES (3,'Kiwi',20); 53 | INSERT INTO ##TableB VALUES (4,NULL,NULL); 54 | ``` 55 | 56 | ---------------------------- 57 | 58 | 1. [Introduction](01%20-%20Introduction.md) 59 | 2. [SQL Processing Order](02%20-%20SQL%20Query%20Processing%20Order.md) 60 | 3. [Table Types](03%20-%20Table%20Types.md) 61 | 4. [Equi, Theta, and Natural Joins](04%20-%20Equi%2C%20Theta%2C%20and%20Natural%20Joins.md) 62 | 5. [Inner Joins](05%20-%20Inner%20Join.md) 63 | 6. [Outer Joins](06%20-%20Outer%20Joins.md) 64 | 7. [Full Outer Joins](07%20-%20Full%20Outer%20Join.md) 65 | 8. [Cross Joins](08%20-%20Cross%20Join.md) 66 | 9. [Semi and Anti Joins](09%20-%20Semi%20and%20Anti%20Joins.md) 67 | 10. [Any, All, and Some](10%20-%20Any%2C%20All%2C%20and%20Some.md) 68 | 11. [Self Joins](11%20-%20Self%20Join.md) 69 | 12. [Relational Division](12%20-%20Relational%20Division.md) 70 | 13. [Set Operations](13%20-%20Set%20Operations.md) 71 | 14. [Join Algorithms](14%20-%20Join%20Algorithms.md) 72 | 15. [Exists](15%20-%20Exists.md) 73 | 16. [Complex Joins](16%20-%20Complex%20Joins.md) 74 | 75 | https://advancedsqlpuzzles.com 76 | -------------------------------------------------------------------------------- /Database Articles/Advanced SQL Joins/images/SQLQueryProcessingOrderPage.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Advanced SQL Joins/images/SQLQueryProcessingOrderPage.png -------------------------------------------------------------------------------- /Database Articles/Advanced SQL Joins/images/readme.md: -------------------------------------------------------------------------------- 1 | This directory contains the images associated with Advanced SQL Joins. 2 | 3 | To open the XML file, use [Draw.io](https://www.draw.io/). 4 | 5 | ---- 6 | 7 | **https://advancedsqlpuzzles.com** 8 | -------------------------------------------------------------------------------- /Database Articles/Advanced SQL Joins/readme.md: -------------------------------------------------------------------------------- 1 | # Welcome 2 | 3 |       Joining tables in SQL requires a good understanding of the data, the relationships between the tables, and the behavior of the different join types. This GitHub repository covers the more advanced concepts of SQL joins and serves as a collection of interesting, odd, and uncommon ways you may see or think of joins in your everyday SQL encounters. 4 | 5 |       I've tried to keep all my examples as concise as possible, and they should serve as a springboard for further exploration. In this repository, there are several markdown documents that showcase different joins and concepts, and I try to show alternative ways in which you can write the SQL statement as a means of understanding their behavior. I have tried to create the documents in such a way they can be read in any order without trying to sound repetitive, but I do offer a recommended reading order that I provide at the end of each document. 6 | 7 |       Although I will talk about the logical processing order and physical join types, any discussion about optimization and best practices is at a cursory level. My intent here is not to show best practices or optimization methods, but to provide a summarization of the different joins that you will encounter in your daily SQL activities and some of the odd and strange joins that you may encounter. To show the various joins, I use a small sample dataset that contains types of fruit that you can find in the `Sample Data.md` markdown file. The sample data has NULL markers but not duplicate data. Feel free to add, subtract, or modify the data and the provided queries to explore their behavior better. 8 | 9 |       I welcome any corrections, additions, debates etc. I've tried to show different joins across all the major database platforms (and not just Microsoft SQL Server), and I am sure there are some new and interesting joins that I have not included here (such as graph joins). Feel free to contact me through this GitHub repository or my WordPress site at https://advancedsqlpuzzles.com. 10 | 11 | --------------------------------------------------------- 12 | 13 | 1. [Introduction](01%20-%20Introduction.md) 14 | 2. [SQL Processing Order](02%20-%20SQL%20Query%20Processing%20Order.md) 15 | 3. [Table Types](03%20-%20Table%20Types.md) 16 | 4. [Equi, Theta, and Natural Joins](04%20-%20Equi%2C%20Theta%2C%20and%20Natural%20Joins.md) 17 | 5. [Inner Joins](05%20-%20Inner%20Join.md) 18 | 6. [Outer Joins](06%20-%20Outer%20Joins.md) 19 | 7. [Full Outer Joins](07%20-%20Full%20Outer%20Join.md) 20 | 8. [Cross Joins](08%20-%20Cross%20Join.md) 21 | 9. [Semi and Anti Joins](09%20-%20Semi%20and%20Anti%20Joins.md) 22 | 10. [Any, All, and Some](10%20-%20Any%2C%20All%2C%20and%20Some.md) 23 | 11. [Self Joins](11%20-%20Self%20Join.md) 24 | 12. [Relational Division](12%20-%20Relational%20Division.md) 25 | 13. [Set Operations](13%20-%20Set%20Operations.md) 26 | 14. [Join Algorithms](14%20-%20Join%20Algorithms.md) 27 | 15. [Exists](15%20-%20Exists.md) 28 | 16. [Complex Joins](16%20-%20Complex%20Joins.md) 29 | 30 | ---------------- 31 | 32 | :mailbox:      If you find any inaccuracies, misspellings, bugs, dead links, etc., please report an issue! No detail is too small, and I appreciate all the help. 33 | 34 | :smile:      Happy coding! 35 | 36 | **https://advancedsqlpuzzles.com** 37 | 38 | -------------------------------------------------------------------------------- /Database Articles/Azure Data Factory Metadata Demo/Customer_1.txt: -------------------------------------------------------------------------------- 1 | Name 2 | Thales of Miletus 3 | Isaac Newton 4 | Carl Friedrich Gauss 5 | E.F. Codd -------------------------------------------------------------------------------- /Database Articles/Azure Data Factory Metadata Demo/Customer_2.txt: -------------------------------------------------------------------------------- 1 | Name 2 | Alan Turing 3 | Grace Hopper 4 | charles babbage -------------------------------------------------------------------------------- /Database Articles/Azure Data Factory Metadata Demo/Customer_3.txt: -------------------------------------------------------------------------------- 1 | Name 2 | Kurt Godel 3 | Bertrand Russell 4 | Georg Cantor 5 | -------------------------------------------------------------------------------- /Database Articles/Azure Data Factory Metadata Demo/Data Factory Metadata Demo PDF.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Azure Data Factory Metadata Demo/Data Factory Metadata Demo PDF.pdf -------------------------------------------------------------------------------- /Database Articles/Azure Data Factory Metadata Demo/Data Factory Metadata Demo Powerpoint.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Azure Data Factory Metadata Demo/Data Factory Metadata Demo Powerpoint.pptx -------------------------------------------------------------------------------- /Database Articles/Azure Data Factory Metadata Demo/Data Factory SQL DDL Scripts.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA demo; 2 | GO 3 | -------------------------------------------------------- 4 | -------------------------------------------------------- 5 | CREATE TYPE demo.CustomersTableType AS TABLE( 6 | [CustomerName] [varchar](100) NOT NULL) 7 | GO 8 | -------------------------------------------------------- 9 | -------------------------------------------------------- 10 | CREATE TABLE demo.Customers 11 | ( 12 | InsertDate DATETIME NULL DEFAULT GETDATE(), 13 | CustomerName VARCHAR(100) NULL 14 | ) 15 | GO 16 | -------------------------------------------------------- 17 | -------------------------------------------------------- 18 | CREATE TABLE demo.CustomersMetadata 19 | ( 20 | InsertDate DATETIME NOT NULL DEFAULT GETDATE(), 21 | CustomerName VARCHAR(MAX), 22 | File_ItemName VARCHAR(MAX) NULL, 23 | File_ItemType VARCHAR(MAX) NULL, 24 | File_Size INT NULL, 25 | File_LastModified datetime NULL, 26 | File_ContentMD5 VARCHAR(MAX) NULL, 27 | File_Structure VARCHAR(MAX) NULL, 28 | File_ColumnCount INT NULL, 29 | File_Exists BIT NULL, 30 | System_DataFactoryName VARCHAR(MAX) NULL, 31 | System_PipelineName VARCHAR(MAX) NULL, 32 | System_PipelineRunId VARCHAR(MAX) NULL, 33 | System_PipelineTriggerType VARCHAR(MAX) NULL, 34 | System_PipelineTriggerId VARCHAR(MAX) NULL, 35 | System_PipelineTriggerName VARCHAR(MAX) NULL, 36 | System_PipelineTriggerTime VARCHAR(MAX) NULL, 37 | System_PipelineGroupID VARCHAR(MAX) NULL, 38 | System_PipelineTriggeredByPipelineName VARCHAR(MAX) NULL, 39 | System_PipelineTriggerByPipelineRunId VARCHAR(MAX) NULL 40 | ); 41 | GO 42 | -------------------------------------------------------- 43 | -------------------------------------------------------- 44 | CREATE PROCEDURE demo.SpInsertCustomersTable 45 | @pCustomersTableType demo.CustomersTableType READONLY, 46 | @pInsertDate DATETIME 47 | AS 48 | BEGIN 49 | 50 | INSERT INTO demo.Customers (InsertDate, CustomerName) 51 | SELECT @pInsertDate, CustomerName 52 | FROM @pCustomersTableType; 53 | 54 | END; 55 | GO 56 | -------------------------------------------------------- 57 | -------------------------------------------------------- 58 | CREATE OR ALTER PROCEDURE demo.SpInsertCustomersMetadata 59 | @pCustomersTableType demo.CustomersTableType READONLY 60 | ,@pFile_ItemName VARCHAR(MAX) NULL 61 | ,@pFile_ItemType VARCHAR(MAX) NULL 62 | ,@pFile_Size INT NULL 63 | ,@pFile_LastModified datetime NULL 64 | ,@pFile_ContentMD5 VARCHAR(MAX) NULL 65 | ,@pFile_Structure VARCHAR(MAX) NULL 66 | ,@pFile_ColumnCount INT NULL 67 | ,@pFile_Exists BIT NULL 68 | ,@pSystem_DataFactoryName VARCHAR(MAX) NULL 69 | ,@pSystem_PipelineName VARCHAR(MAX) NULL 70 | ,@pSystem_PipelineRunId VARCHAR(MAX) NULL 71 | ,@pSystem_PipelineTriggerType VARCHAR(MAX) NULL 72 | ,@pSystem_PipelineTriggerId VARCHAR(MAX) NULL 73 | ,@pSystem_PipelineTriggerName VARCHAR(MAX) NULL 74 | ,@pSystem_PipelineTriggerTime VARCHAR(MAX) NULL 75 | ,@pSystem_PipelineGroupID VARCHAR(MAX) NULL 76 | ,@pSystem_PipelineTriggeredByPipelineName VARCHAR(MAX) NULL 77 | ,@pSystem_PipelineTriggerByPipelineRunId VARCHAR(MAX) NULL 78 | AS 79 | BEGIN 80 | 81 | INSERT INTO demo.CustomersMetadata 82 | ( 83 | CustomerName 84 | ,File_ItemName 85 | ,File_ItemType 86 | ,File_Size 87 | ,File_LastModified 88 | ,File_Contentmd5 89 | ,File_Structure 90 | ,File_ColumnCount 91 | ,File_Exists 92 | ,System_DataFactoryName 93 | ,System_PipelineName 94 | ,System_PipelineRunId 95 | ,System_PipelineTriggerType 96 | ,System_PipelineTriggerId 97 | ,System_PipelineTriggerName 98 | ,System_PipelineTriggerTime 99 | ,System_PipelineGroupID 100 | ,System_PipelineTriggeredByPipelineName 101 | ,System_PipelineTriggerByPipelineRunId 102 | ) 103 | SELECT 104 | CustomerName 105 | ,@pFile_ItemName 106 | ,@pFile_ItemType 107 | ,@pFile_Size 108 | ,@pFile_LastModified 109 | ,@pFile_Contentmd5 110 | ,@pFile_Structure 111 | ,@pFile_ColumnCount 112 | ,@pFile_Exists 113 | ,@pSystem_DataFactoryName 114 | ,@pSystem_PipelineName 115 | ,@pSystem_PipelineRunId 116 | ,@pSystem_PipelineTriggerType 117 | ,@pSystem_PipelineTriggerId 118 | ,@pSystem_PipelineTriggerName 119 | ,@pSystem_PipelineTriggerTime 120 | ,@pSystem_PipelineGroupID 121 | ,@pSystem_PipelineTriggeredByPipelineName 122 | ,@pSystem_PipelineTriggerByPipelineRunId 123 | FROM @pCustomersTableType; 124 | 125 | END 126 | GO 127 | -------------------------------------------------------- 128 | -------------------------------------------------------- 129 | -------------------------------------------------------------------------------- /Database Articles/Azure Data Factory Metadata Demo/readme.md: -------------------------------------------------------------------------------- 1 | # Data Factory Metadata Demo 2 | 3 | This directory contains a demo to understand what metadata is available with Azure Data Factory. 4 | 5 | :exclamation:      This presentation was created in late 2021, and Microsoft Azure may have updated certain features and options. If any information in this presentation becomes outdated or needs to be updated, kindly notify me. Thank you! 6 | 7 | ## About 8 | 9 | In this demo, I create several pipelines to import text files into a SQL Server database and append all Azure Data Factory metadata from both the text files 10 | and the Data Factory pipeline. 11 | 12 | This demo covers the following topics: 13 | * File and Data Factory Pipeline Metadata 14 | * Parameters and Variables 15 | * User-Defined Table Types 16 | 17 | ## Getting Started 18 | 19 | To get started, download the `Data Factory Metadata Demo PDF.pdf` and follow along with each slide. 20 | 21 | In this directory, you will find the following files: 22 | * Sample text files (`Customer_1.txt`,`Customer_2.txt`,`Customer_3.txt`) that we will import using Azure Data Factory. 23 | * A script (`Data Factory SQL DDL Scripts.sql`) to create the tables and stored procedure we will use in this demo. 24 | 25 | I've also included the PowerPoint presentation (`Data Factory MetaData Demo PowerPoint.pptx`) that you can download and add notes or modify as needed. 26 | 27 | ------------------------------------------------ 28 | 29 | :mailbox:      If you find any inaccuracies, misspellings, bugs, dead links, etc., please report an issue! No detail is too small, and I appreciate all the help. 30 | 31 | :smile:      Happy coding! 32 | 33 | **https://advancedsqlpuzzles.com** 34 | -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/Azure Databricks Spark Hive Demo PDF.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Azure Databricks Hive Demo/Azure Databricks Spark Hive Demo PDF.pdf -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/Azure Databricks Spark Hive Demo Powerpoint.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Azure Databricks Hive Demo/Azure Databricks Spark Hive Demo Powerpoint.pptx -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/Parts.csv: -------------------------------------------------------------------------------- 1 | PartId,PartName,Color,Weight,City 2 | 1,Nut,Red,12,London 3 | 2,Bolt,Green,17,Paris 4 | 3,Screw,Blue,17,Oslo 5 | 4,Screw,Red,14,London 6 | 5,Cam,Blue,12,Paris 7 | 6,Cog,Red,19,London -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/Shipments.csv: -------------------------------------------------------------------------------- 1 | ShipmentId,SupplierId,PartId,Quantity 2 | 1,1,1,300 3 | 2,1,2,200 4 | 3,1,3,400 5 | 4,1,4,200 6 | 5,1,5,100 7 | 6,1,6,100 8 | 7,2,1,300 9 | 8,2,2,400 10 | 9,3,2,200 11 | 10,4,2,200 12 | 11,4,4,300 13 | 12,4,5,400 -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/Suppliers.csv: -------------------------------------------------------------------------------- 1 | SupplierId,SupplierName,Status,City 2 | 1,Smith,20,London 3 | 2,Jones,10,Paris 4 | 3,Blake,30,Paris 5 | 4,Clark,20,London 6 | 5,Adams,30,Athens -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/SuppliersAndParts.dbc: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Azure Databricks Hive Demo/SuppliersAndParts.dbc -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/SuppliersAndPartsDDL.sql: -------------------------------------------------------------------------------- 1 | CREATE SCHEMA supp_parts_hive; 2 | GO 3 | 4 | DROP TABLE IF EXISTS supp_parts_hive.Shipments; 5 | DROP TABLE IF EXISTS supp_parts_hive.Suppliers; 6 | DROP TABLE IF EXISTS supp_parts_hive.Parts; 7 | GO 8 | 9 | 10 | CREATE TABLE supp_parts_hive.Suppliers 11 | ( 12 | SupplierId int NOT NULL PRIMARY KEY, 13 | SupplierName varchar(16) NOT NULL, 14 | Status int NOT NULL, 15 | City varchar(20) NOT NULL, 16 | InsertDate DATETIME DEFAULT GETDATE() NOT NULL 17 | ); 18 | GO 19 | 20 | 21 | CREATE TABLE supp_parts_hive.Parts 22 | ( 23 | PartId int NOT NULL PRIMARY KEY, 24 | PartName varchar(18) NOT NULL, 25 | Color varchar(10) NOT NULL, 26 | Weight decimal(4,1) NOT NULL, 27 | City varchar(20) NOT NULL, 28 | InsertDate DATETIME DEFAULT GETDATE() NOT NULL 29 | ); 30 | GO 31 | 32 | 33 | CREATE TABLE supp_parts_hive.Shipments 34 | ( 35 | ShipmentId int NOT NULL PRIMARY KEY, 36 | SupplierId int, 37 | PartId int, 38 | Quantity int NOT NULL, 39 | InsertDate DATETIME NOT NULL DEFAULT GETDATE() 40 | ); 41 | GO -------------------------------------------------------------------------------- /Database Articles/Azure Databricks Hive Demo/readme.md: -------------------------------------------------------------------------------- 1 | # Databricks Spark Hive Demo 2 | 3 | **https://advancedsqlpuzzles.com** 4 | 5 | This directory contains a demo to understand how to connect Databricks to an Azure Data Lake and SQL Server. 6 | 7 | :exclamation: This presentation was created in late 2021, and Microsoft Azure may have updated certain features and options. If any information in this presentation becomes outdated or needs to be updated, kindly notify me. Thank you! 8 | 9 | ## About 10 | 11 | **In this demo, we will perform the following:** 12 | 1. Connect Databricks to an Azure Key Vault 13 | 2. Connect Databricks to an Azure Data Lake 14 | 3. Create an ETL process to import CSV files from an Azure Data Lake 15 | 4. Merge the data into Hive tables 16 | 5. Insert the data into a SQL Server database 17 | 6. Automate the ETL via an Azure Data Factory pipeline 18 | 19 | ## Getting Started 20 | 21 | To get started, download the `Databricks Spark Hive Demo.pdf` and follow along with each slide. 22 | 23 | In this directory, you will find the following files: 24 | 25 | * Sample text files (`Parts.txt`,`Shipments.txt`,`Suppliers.txt`) that we will import using Databricks. 26 | * The Databricks notebooks (`SuppliersAndParts.dbc`) that connect the Key Vault, Data Lake, SQL Server, etc., and perform the ETL. 27 | * The DDL statements (`SuppliersAndPartsDDL.sql`) to create the tables in SQL Server. 28 | 29 | I've also included the PowerPoint presentation (`Databricks Spark Hive Demo PowerPoint.pptx`) that you can download and add notes or modify as needed. 30 | 31 | --------------------------------------------- 32 | 33 | :mailbox:      If you find any inaccuracies, misspellings, bugs, dead links, etc., please report an issue! No detail is too small, and I appreciate all the help. 34 | 35 | :smile:      Happy coding! 36 | -------------------------------------------------------------------------------- /Database Articles/Behavior Of Nulls/images/Truth_Tables_Three_Valued_Logic.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Behavior Of Nulls/images/Truth_Tables_Three_Valued_Logic.png -------------------------------------------------------------------------------- /Database Articles/Behavior Of Nulls/images/readme.md: -------------------------------------------------------------------------------- 1 | This directory contains the images associated with Behavior Of Nulls. 2 | 3 | ---- 4 | 5 | **https://advancedsqlpuzzles.com** 6 | 7 | -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/Database_Dependency_Analysis.xlsx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/smpetersgithub/AdvancedSQLPuzzles/b69367c600cd426e7a96014889c3eb525eb1ef57/Database Articles/Database Dependencies/Database_Dependency_Analysis.xlsx -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/README.MD: -------------------------------------------------------------------------------- 1 | # SQL Server Database Dependencies 2 | 3 | The following documentation is designed to help developers understand the `sys.sql_expression_dependencies` table in Microsoft SQL Server. This repository includes an example walk through of various dependencies, how they interact with the `sys.sql_expression_dependencies` table, and the corresponding scripts essential for grasping this table's functionality and data representation. These scripts also serve as a comprehensive repository of dependencies, including some you may have yet to encounter or consider. 4 | 5 | For this documentation, I chose to use GitBook, which you can access with the following link. 6 | 7 | https://advanced-sql-puzzles.gitbook.io/database-dependencies 8 | 9 | The documentation covers the following dependencies and their interactions with the `sys.sql_expression_dependencies` table. 10 | 11 | | ID | Topic | 12 | |-----|--------------------------------------------| 13 | | 1 | Cross Schema Dependencies | 14 | | 2 | Invalid Stored Procedures | 15 | | 3 | Numbered Stored Procedures | 16 | | 4 | Ambiguous References | 17 | | 5 | Part Naming Conventions | 18 | | 6 | Part Naming Conventions - Caller Dependent | 19 | | 7 | Dropping Objects | 20 | | 8 | Dropping Objects Then Recreating | 21 | | 9 | Self-Referencing Objects | 22 | | 10 | Object Aliases | 23 | | 11 | Schemabindings | 24 | | 12 | Synonyms | 25 | | 13 | Triggers - DML | 26 | | 14 | Triggers - DDL Database Level | 27 | | 15 | Triggers - DDL Server Level - Table Insert | 28 | | 16 | Partition Functions | 29 | | 17 | Defaults and Rules | 30 | | 18 | Contracts, Queues and Message Types | 31 | | 19 | Sequences | 32 | | 20 | User Defined Data Types | 33 | | 21 | User Defined Table Types | 34 | | 22 | Check Constraints | 35 | | 23 | Foreign Key Constraints | 36 | | 24 | Computed Columns | 37 | | 25 | Masked Functions | 38 | | 26 | Indexes - Table | 39 | | 27 | Indexes - Filtered NonClustered | 40 | | 28 | Indexes - Filtered XML | 41 | | 29 | Statistics - Filtered | 42 | | 30 | XML Schema Collection | 43 | | 31 | XML Methods | 44 | -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/02_Cross_Schema_Dependencies.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS schemaA.tbl_example_02_schemaA; 6 | DROP TABLE IF EXISTS dbo.tbl_example_02_dbo; 7 | DROP VIEW IF EXISTS dbo.vw_example_02; 8 | GO 9 | 10 | ------------------------------------------------------- 11 | ------------------------------------------------------- 12 | ------------------------------------------------------- 13 | USE foo; 14 | GO 15 | 16 | CREATE TABLE schemaA.tbl_example_02_schemaA 17 | ( 18 | OrderID INT, 19 | ProductID INT, 20 | Quantity INT, 21 | UnitPrice MONEY 22 | ); 23 | GO 24 | 25 | CREATE TABLE dbo.tbl_example_02_dbo 26 | ( 27 | OrderID INT, 28 | ProductID INT, 29 | Quantity INT, 30 | UnitPrice MONEY 31 | ); 32 | GO 33 | 34 | CREATE VIEW dbo.vw_example_02 AS 35 | SELECT 1 AS myValue 36 | FROM schemaA.tbl_example_02_schemaA CROSS JOIN 37 | dbo.tbl_example_02_dbo; 38 | GO 39 | 40 | ------------------------------------------------------- 41 | ------------------------------------------------------- 42 | ------------------------------------------------------- 43 | USE foo; 44 | GO 45 | 46 | DECLARE @vTruncate SMALLINT = 0; 47 | IF @vTruncate = 1 48 | BEGIN 49 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 50 | END; 51 | GO 52 | ------------------------------------------------------- 53 | USE foo; 54 | GO 55 | 56 | INSERT INTO foo.dbo.sql_expression_dependencies 57 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 58 | SELECT '02', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 59 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 60 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 61 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 62 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 63 | sys.server_triggers e ON a.referencing_id = e.object_id; 64 | GO 65 | 66 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 67 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 68 | FROM sys.objects 69 | GO 70 | 71 | ------------------------------------------------------- 72 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 73 | GO 74 | 75 | ------------------------------------------------------- 76 | USE foo; 77 | GO 78 | 79 | DECLARE @vDropObjects SMALLINT = 1; 80 | IF @vDropObjects = 1 81 | BEGIN 82 | DROP TABLE IF EXISTS schemaA.tbl_example_02_schemaA; 83 | DROP TABLE IF EXISTS dbo.tbl_example_02_dbo; 84 | DROP VIEW IF EXISTS dbo.vw_example_02; 85 | END; 86 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/03_Invalid_Stored_Procedures.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP PROCEDURE IF EXISTS dbo.sp_example_03; 6 | GO 7 | --------------------------------------------- 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | USE foo; 11 | GO 12 | 13 | CREATE PROCEDURE dbo.sp_example_03 AS 14 | BEGIN 15 | SELECT * 16 | FROM dbo.tbl_does_not_exist_example_03; 17 | END; 18 | GO 19 | 20 | ------------------------------------------------------- 21 | ------------------------------------------------------- 22 | ------------------------------------------------------- 23 | USE foo; 24 | GO 25 | 26 | DECLARE @vTruncate SMALLINT = 0; 27 | IF @vTruncate = 1 28 | BEGIN 29 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 30 | END; 31 | GO 32 | ------------------------------------------------------- 33 | USE foo; 34 | GO 35 | 36 | INSERT INTO foo.dbo.sql_expression_dependencies 37 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 38 | SELECT '03', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 39 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 40 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 41 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 42 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 43 | sys.server_triggers e ON a.referencing_id = e.object_id; 44 | GO 45 | 46 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 47 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 48 | FROM sys.objects 49 | GO 50 | 51 | ------------------------------------------------------- 52 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 53 | GO 54 | 55 | ------------------------------------------------------- 56 | USE foo; 57 | GO 58 | 59 | DECLARE @vDropObjects SMALLINT = 1; 60 | IF @vDropObjects = 1 61 | BEGIN 62 | DROP PROCEDURE IF EXISTS dbo.sp_example_03; 63 | END; 64 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/04_Numbered_Stored_Procedures.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_04_a; 6 | DROP TABLE IF EXISTS dbo.tbl_example_04_b; 7 | DROP PROCEDURE IF EXISTS dbo.sp_example_04; 8 | GO 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE TABLE dbo.tbl_example_04_a 16 | ( 17 | OrderID INT, 18 | ProductID INT, 19 | Quantity INT, 20 | UnitPrice MONEY 21 | ); 22 | GO 23 | 24 | CREATE TABLE dbo.tbl_example_04_b 25 | ( 26 | OrderID INT, 27 | ProductID INT, 28 | Quantity INT, 29 | UnitPrice MONEY 30 | ); 31 | GO 32 | 33 | CREATE PROCEDURE dbo.sp_example_04;1 AS 34 | BEGIN 35 | SELECT * 36 | FROM dbo.tbl_example_04_a; 37 | END; 38 | GO 39 | 40 | CREATE PROCEDURE dbo.sp_example_04;2 AS 41 | BEGIN 42 | SELECT * 43 | FROM dbo.tbl_example_04_b; 44 | END; 45 | GO 46 | 47 | ------------------------------------------------------- 48 | ------------------------------------------------------- 49 | ------------------------------------------------------- 50 | USE foo; 51 | GO 52 | 53 | DECLARE @vTruncate SMALLINT = 0; 54 | IF @vTruncate = 1 55 | BEGIN 56 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 57 | END; 58 | GO 59 | ------------------------------------------------------- 60 | USE foo; 61 | GO 62 | 63 | INSERT INTO foo.dbo.sql_expression_dependencies 64 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 65 | SELECT '04', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 66 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 67 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 68 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 69 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 70 | sys.server_triggers e ON a.referencing_id = e.object_id; 71 | GO 72 | 73 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 74 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 75 | FROM sys.objects 76 | GO 77 | 78 | ------------------------------------------------------- 79 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 80 | GO 81 | 82 | --------------------------------------------- 83 | USE foo; 84 | GO 85 | 86 | DECLARE @vDropObjects SMALLINT = 1; 87 | IF @vDropObjects = 1 88 | BEGIN 89 | DROP TABLE IF EXISTS dbo.tbl_example_04_a; 90 | DROP TABLE IF EXISTS dbo.tbl_example_04_b; 91 | DROP PROCEDURE IF EXISTS dbo.sp_example_04; 92 | END; 93 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/05_Ambiguous_References.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP FUNCTION IF EXISTS dbo.fn_example_05; 6 | DROP PROCEDURE IF EXISTS dbo.sp_example_05; 7 | DROP TABLE IF EXISTS dbo.tbl_example_05; 8 | GO 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE TABLE dbo.tbl_example_05 16 | ( 17 | OrderID INT, 18 | ProductID INT, 19 | Quantity INT, 20 | UnitPrice MONEY 21 | ); 22 | GO 23 | 24 | CREATE FUNCTION dbo.fn_example_05(@intToCheck INT) RETURNS VARCHAR(MAX) AS 25 | BEGIN 26 | RETURN CASE WHEN @intToCheck IS NULL THEN -1 ELSE @intToCheck END; 27 | END; 28 | GO 29 | 30 | CREATE PROCEDURE dbo.sp_example_05 (@inputInt INT) AS 31 | BEGIN 32 | SELECT dbo.fn_example_05(tbl_example_05.OrderID) 33 | FROM dbo.tbl_example_05; 34 | END; 35 | GO 36 | 37 | ------------------------------------------------------- 38 | ------------------------------------------------------- 39 | ------------------------------------------------------- 40 | USE foo; 41 | GO 42 | 43 | DECLARE @vTruncate SMALLINT = 0; 44 | IF @vTruncate = 1 45 | BEGIN 46 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 47 | END; 48 | GO 49 | ------------------------------------------------------- 50 | USE foo; 51 | GO 52 | 53 | INSERT INTO foo.dbo.sql_expression_dependencies 54 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 55 | SELECT '05', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 56 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 57 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 58 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 59 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 60 | sys.server_triggers e ON a.referencing_id = e.object_id; 61 | GO 62 | 63 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 64 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 65 | FROM sys.objects 66 | GO 67 | 68 | ------------------------------------------------------- 69 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 70 | GO 71 | 72 | --------------------------------------------- 73 | USE foo; 74 | GO 75 | 76 | DECLARE @vDropObjects SMALLINT = 1; 77 | IF @vDropObjects = 1 78 | BEGIN 79 | DROP FUNCTION IF EXISTS dbo.fn_example_05; 80 | DROP PROCEDURE IF EXISTS dbo.sp_example_05; 81 | DROP TABLE IF EXISTS dbo.tbl_example_05; 82 | END; 83 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/06_Part_Naming_Conventions.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP VIEW IF EXISTS dbo.vw_four_part_name_example_06; 6 | DROP VIEW IF EXISTS dbo.vw_three_part_name_example_06; 7 | DROP VIEW IF EXISTS dbo.vw_two_part_name_example_06; 8 | DROP VIEW IF EXISTS dbo.vw_one_part_name_example_06; 9 | DROP TABLE IF EXISTS dbo.tbl_example_06; 10 | GO 11 | 12 | ------------------------------------------------------- 13 | ------------------------------------------------------- 14 | ------------------------------------------------------- 15 | USE foo; 16 | GO 17 | 18 | CREATE TABLE dbo.tbl_example_06 19 | ( 20 | OrderID INT, 21 | ProductID INT, 22 | Quantity INT, 23 | UnitPrice MONEY 24 | ); 25 | GO 26 | 27 | CREATE VIEW dbo.vw_one_part_name_example_06 AS 28 | SELECT * 29 | FROM tbl_example_06; --one-part 30 | GO 31 | 32 | CREATE VIEW dbo.vw_two_part_name_example_06 AS 33 | SELECT * 34 | FROM dbo.tbl_example_06; --two-part 35 | GO 36 | 37 | CREATE VIEW dbo.vw_three_part_name_example_06 AS 38 | SELECT * 39 | FROM foo.dbo.tbl_example_06; --three-part 40 | GO 41 | 42 | CREATE VIEW dbo.vw_four_part_name_example_06 AS 43 | SELECT * 44 | FROM [DESKTOP-D324ETP\SQLEXPRESS01].foo.dbo.tbl_example_06; --four-part 45 | GO 46 | 47 | ------------------------------------------------------- 48 | ------------------------------------------------------- 49 | ------------------------------------------------------- 50 | USE foo; 51 | GO 52 | 53 | DECLARE @vTruncate SMALLINT = 0; 54 | IF @vTruncate = 1 55 | BEGIN 56 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 57 | END; 58 | GO 59 | ------------------------------------------------------- 60 | USE foo; 61 | GO 62 | 63 | INSERT INTO foo.dbo.sql_expression_dependencies 64 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 65 | SELECT '06', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 66 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 67 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 68 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 69 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 70 | sys.server_triggers e ON a.referencing_id = e.object_id; 71 | GO 72 | 73 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 74 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 75 | FROM sys.objects 76 | GO 77 | 78 | ------------------------------------------------------- 79 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 80 | GO 81 | 82 | ------------------------------------------------------- 83 | USE foo; 84 | GO 85 | 86 | DECLARE @vDropObjects SMALLINT = 1; 87 | IF @vDropObjects = 1 88 | BEGIN 89 | DROP VIEW IF EXISTS dbo.vw_four_part_name_example_06; 90 | DROP VIEW IF EXISTS dbo.vw_three_part_name_example_06; 91 | DROP VIEW IF EXISTS dbo.vw_two_part_name_example_06; 92 | DROP VIEW IF EXISTS dbo.vw_one_part_name_example_06; 93 | DROP TABLE IF EXISTS dbo.tbl_example_06; 94 | END; 95 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/07_Part_Naming_Conventions_Caller_Dependent.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP PROCEDURE IF EXISTS dbo.sp_example_07_a; 6 | DROP PROCEDURE IF EXISTS dbo.sp_example_07_b; 7 | GO 8 | 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE PROCEDURE dbo.sp_example_07_a AS 16 | BEGIN 17 | PRINT 'Hello World'; 18 | END; 19 | GO 20 | 21 | CREATE PROCEDURE dbo.sp_example_07_b AS 22 | BEGIN 23 | EXECUTE sp_example_07_a 24 | END; 25 | GO 26 | 27 | ------------------------------------------------------- 28 | ------------------------------------------------------- 29 | ------------------------------------------------------- 30 | USE foo; 31 | GO 32 | 33 | DECLARE @vTruncate SMALLINT = 0; 34 | IF @vTruncate = 1 35 | BEGIN 36 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 37 | END; 38 | GO 39 | ------------------------------------------------------- 40 | USE foo; 41 | GO 42 | 43 | INSERT INTO foo.dbo.sql_expression_dependencies 44 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 45 | SELECT '07', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 46 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 47 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 48 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 49 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 50 | sys.server_triggers e ON a.referencing_id = e.object_id; 51 | GO 52 | 53 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 54 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 55 | FROM sys.objects 56 | GO 57 | 58 | ------------------------------------------------------- 59 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 60 | GO 61 | 62 | --------------------------------------------- 63 | USE foo; 64 | GO 65 | 66 | DECLARE @vDropObjects SMALLINT = 1; 67 | IF @vDropObjects = 1 68 | BEGIN 69 | DROP PROCEDURE IF EXISTS dbo.sp_example_07_a; 70 | DROP PROCEDURE IF EXISTS dbo.sp_example_07_b; 71 | END; 72 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/08_Dropping_Objects.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP VIEW IF EXISTS dbo.vw_example_08; 6 | DROP TABLE IF EXISTS dbo.tbl_example_08 7 | GO 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | USE foo; 12 | GO 13 | 14 | CREATE TABLE dbo.tbl_example_08 15 | ( 16 | OrderID INT, 17 | ProductID INT, 18 | Quantity INT, 19 | UnitPrice MONEY 20 | ); 21 | GO 22 | 23 | CREATE VIEW dbo.vw_example_08 AS 24 | SELECT * 25 | FROM dbo.tbl_example_08 26 | GO 27 | 28 | DROP TABLE dbo.tbl_example_08; 29 | GO 30 | 31 | ------------------------------------------------------- 32 | ------------------------------------------------------- 33 | ------------------------------------------------------- 34 | USE foo; 35 | GO 36 | 37 | DECLARE @vTruncate SMALLINT = 0; 38 | IF @vTruncate = 1 39 | BEGIN 40 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 41 | END; 42 | GO 43 | ------------------------------------------------------- 44 | USE foo; 45 | GO 46 | 47 | INSERT INTO foo.dbo.sql_expression_dependencies 48 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 49 | SELECT '08', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 50 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 51 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 52 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 53 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 54 | sys.server_triggers e ON a.referencing_id = e.object_id; 55 | GO 56 | 57 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 58 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 59 | FROM sys.objects 60 | GO 61 | 62 | ------------------------------------------------------- 63 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 64 | GO 65 | 66 | --------------------------------------------- 67 | USE foo; 68 | GO 69 | 70 | DECLARE @vDropObjects SMALLINT = 1; 71 | IF @vDropObjects = 1 72 | BEGIN 73 | DROP VIEW IF EXISTS dbo.vw_example_08; 74 | DROP TABLE IF EXISTS dbo.tbl_example_08 75 | END; 76 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/09_Dropping_Objects_Then_Recreating.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP VIEW IF EXISTS dbo.vw_example_09; 6 | GO 7 | DROP PROCEDURE IF EXISTS dbo.obj_example_09; 8 | GO 9 | DROP TABLE IF EXISTS dbo.obj_example_09; 10 | GO 11 | --------------------------------------------- 12 | --------------------------------------------- 13 | --------------------------------------------- 14 | USE foo; 15 | GO 16 | 17 | CREATE TABLE dbo.obj_example_09 18 | ( 19 | OrderID INT, 20 | ProductID INT, 21 | Quantity INT, 22 | UnitPrice MONEY 23 | ); 24 | GO 25 | 26 | CREATE VIEW dbo.vw_example_09 AS 27 | SELECT * 28 | FROM dbo.obj_example_09 29 | GO 30 | 31 | DROP TABLE dbo.obj_example_09; 32 | GO 33 | 34 | CREATE PROCEDURE dbo.obj_example_09 AS 35 | BEGIN 36 | PRINT('Hello World'); 37 | END; 38 | GO 39 | 40 | ------------------------------------------------------- 41 | ------------------------------------------------------- 42 | ------------------------------------------------------- 43 | USE foo; 44 | GO 45 | 46 | DECLARE @vTruncate SMALLINT = 0; 47 | IF @vTruncate = 1 48 | BEGIN 49 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 50 | END; 51 | GO 52 | ------------------------------------------------------- 53 | USE foo; 54 | GO 55 | 56 | INSERT INTO foo.dbo.sql_expression_dependencies 57 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 58 | SELECT '09', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 59 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 60 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 61 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 62 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 63 | sys.server_triggers e ON a.referencing_id = e.object_id; 64 | GO 65 | 66 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 67 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 68 | FROM sys.objects 69 | GO 70 | 71 | ------------------------------------------------------- 72 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 73 | GO 74 | 75 | --------------------------------------------- 76 | USE foo; 77 | GO 78 | 79 | DECLARE @vDropObjects SMALLINT = 1; 80 | IF @vDropObjects = 1 81 | BEGIN 82 | DROP VIEW IF EXISTS dbo.vw_example_09; 83 | DROP PROCEDURE IF EXISTS dbo.obj_example_09; 84 | END; 85 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/10_Self_Referencing_Objects.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP FUNCTION IF EXISTS dbo.fn_example_10; 6 | DROP PROCEDURE IF EXISTS dbo.sp_example_10; 7 | GO 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | USE foo; 12 | GO 13 | 14 | CREATE FUNCTION dbo.fn_example_10 (@vInputString VARCHAR(100)) RETURNS VARCHAR(100) AS 15 | BEGIN 16 | DECLARE @vResult VARCHAR(100); 17 | SET @vResult = dbo.fn_example_10('Hello World'); 18 | RETURN @vResult; 19 | END; 20 | GO 21 | 22 | CREATE PROCEDURE dbo.sp_example_10 AS 23 | BEGIN 24 | EXEC dbo.sp_example_10; 25 | END; 26 | GO 27 | 28 | ------------------------------------------------------- 29 | ------------------------------------------------------- 30 | ------------------------------------------------------- 31 | USE foo; 32 | GO 33 | 34 | DECLARE @vTruncate SMALLINT = 0; 35 | IF @vTruncate = 1 36 | BEGIN 37 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 38 | END; 39 | GO 40 | ------------------------------------------------------- 41 | USE foo; 42 | GO 43 | 44 | INSERT INTO foo.dbo.sql_expression_dependencies 45 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 46 | SELECT '10', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 47 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 48 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 49 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 50 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 51 | sys.server_triggers e ON a.referencing_id = e.object_id; 52 | GO 53 | 54 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 55 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 56 | FROM sys.objects 57 | GO 58 | 59 | ------------------------------------------------------- 60 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 61 | GO 62 | 63 | --------------------------------------------- 64 | USE foo; 65 | GO 66 | 67 | DECLARE @vDropObjects SMALLINT = 1; 68 | IF @vDropObjects = 1 69 | BEGIN 70 | DROP FUNCTION IF EXISTS dbo.fn_example_10; 71 | DROP PROCEDURE IF EXISTS dbo.sp_example_10; 72 | END; 73 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/11_Object_Aliases.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP PROCEDURE IF EXISTS dbo.sp_example_11; 6 | DROP TABLE IF EXISTS tbl_example_11; 7 | GO 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | USE foo; 12 | GO 13 | 14 | CREATE TABLE dbo.tbl_example_11 15 | ( 16 | OrderID INT, 17 | ProductID INT, 18 | Quantity INT, 19 | UnitPrice MONEY 20 | ); 21 | GO 22 | 23 | CREATE PROCEDURE dbo.sp_example_11 AS 24 | BEGIN 25 | UPDATE alias_example_11 26 | SET Quantity = 0 27 | FROM dbo.tbl_example_11 AS alias_example_11; 28 | 29 | UPDATE alias_example_11 30 | SET Quantity = 0 31 | FROM #temp_table AS alias_example_11; 32 | END; 33 | GO 34 | 35 | ------------------------------------------------------- 36 | ------------------------------------------------------- 37 | ------------------------------------------------------- 38 | USE foo; 39 | GO 40 | 41 | DECLARE @vTruncate SMALLINT = 0; 42 | IF @vTruncate = 1 43 | BEGIN 44 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 45 | END; 46 | GO 47 | ------------------------------------------------------- 48 | USE foo; 49 | GO 50 | 51 | INSERT INTO foo.dbo.sql_expression_dependencies 52 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 53 | SELECT '11', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 54 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 55 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 56 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 57 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 58 | sys.server_triggers e ON a.referencing_id = e.object_id; 59 | GO 60 | 61 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 62 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 63 | FROM sys.objects 64 | GO 65 | 66 | ------------------------------------------------------- 67 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 68 | GO 69 | 70 | --------------------------------------------- 71 | USE foo; 72 | GO 73 | 74 | DECLARE @vDropObjects SMALLINT = 1; 75 | IF @vDropObjects = 1 76 | BEGIN 77 | DROP PROCEDURE IF EXISTS dbo.sp_example_11; 78 | DROP TABLE IF EXISTS tbl_example_11; 79 | END; 80 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/12_Schemabindings.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP FUNCTION IF EXISTS dbo.fn_example_12; 6 | DROP VIEW IF EXISTS dbo.vw_example_12; 7 | DROP TABLE IF EXISTS dbo.tbl_example_12; 8 | GO 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE TABLE dbo.tbl_example_12 16 | ( 17 | OrderID INT, 18 | ProductID INT, 19 | Quantity INT, 20 | UnitPrice MONEY 21 | ); 22 | GO 23 | 24 | CREATE FUNCTION dbo.fn_example_12() RETURNS INT 25 | WITH SCHEMABINDING AS 26 | BEGIN 27 | DECLARE @result INT; 28 | 29 | SELECT TOP 1 30 | @result = OrderID 31 | FROM dbo.tbl_example_12; 32 | 33 | RETURN @result; 34 | END; 35 | GO 36 | 37 | CREATE VIEW dbo.vw_example_12 38 | WITH SCHEMABINDING AS 39 | SELECT OrderID 40 | FROM dbo.tbl_example_12; 41 | GO 42 | 43 | ------------------------------------------------------- 44 | ------------------------------------------------------- 45 | ------------------------------------------------------- 46 | USE foo; 47 | GO 48 | 49 | DECLARE @vTruncate SMALLINT = 0; 50 | IF @vTruncate = 1 51 | BEGIN 52 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 53 | END; 54 | GO 55 | ------------------------------------------------------- 56 | USE foo; 57 | GO 58 | 59 | INSERT INTO foo.dbo.sql_expression_dependencies 60 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 61 | SELECT '12', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 62 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 63 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 64 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 65 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 66 | sys.server_triggers e ON a.referencing_id = e.object_id; 67 | GO 68 | 69 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 70 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 71 | FROM sys.objects 72 | GO 73 | 74 | ------------------------------------------------------- 75 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 76 | GO 77 | 78 | --------------------------------------------- 79 | USE foo; 80 | GO 81 | 82 | DECLARE @vDropObjects SMALLINT = 1; 83 | IF @vDropObjects = 1 84 | BEGIN 85 | DROP FUNCTION IF EXISTS dbo.fn_example_12; 86 | DROP VIEW IF EXISTS dbo.vw_example_12; 87 | DROP TABLE IF EXISTS dbo.tbl_example_12; 88 | END; 89 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/13_Synonyms.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_13; 6 | DROP SYNONYM IF EXISTS dbo.syn_invalid_example_13; 7 | DROP SYNONYM IF EXISTS dbo.syn_example_13; 8 | DROP VIEW IF EXISTS dbo.vw_example_13; 9 | DROP PROCEDURE IF EXISTS dbo.sp_example_13; 10 | GO 11 | --------------------------------------------- 12 | --------------------------------------------- 13 | --------------------------------------------- 14 | USE foo; 15 | GO 16 | 17 | CREATE TABLE dbo.tbl_example_13 18 | ( 19 | OrderID INT, 20 | ProductID INT, 21 | Quantity INT, 22 | UnitPrice MONEY 23 | ); 24 | GO 25 | 26 | --Invalid 27 | CREATE SYNONYM dbo.syn_invalid_example_13 FOR tbl_does_not_exist_13; 28 | GO 29 | 30 | --Valid 31 | CREATE SYNONYM dbo.syn_example_13 FOR tbl_example_13; 32 | GO 33 | 34 | CREATE VIEW dbo.vw_example_13 AS 35 | SELECT * 36 | FROM dbo.syn_example_13; 37 | GO 38 | 39 | CREATE PROCEDURE dbo.sp_example_13 AS 40 | BEGIN 41 | SELECT * FROM dbo.syn_example_13; 42 | END; 43 | GO 44 | 45 | ------------------------------------------------------- 46 | ------------------------------------------------------- 47 | ------------------------------------------------------- 48 | USE foo; 49 | GO 50 | 51 | DECLARE @vTruncate SMALLINT = 0; 52 | IF @vTruncate = 1 53 | BEGIN 54 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 55 | END; 56 | GO 57 | ------------------------------------------------------- 58 | USE foo; 59 | GO 60 | 61 | INSERT INTO foo.dbo.sql_expression_dependencies 62 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 63 | SELECT '13', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 64 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 65 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 66 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 67 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 68 | sys.server_triggers e ON a.referencing_id = e.object_id; 69 | GO 70 | 71 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 72 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 73 | FROM sys.objects 74 | GO 75 | 76 | ------------------------------------------------------- 77 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 78 | GO 79 | 80 | --------------------------------------------- 81 | USE foo; 82 | GO 83 | 84 | DECLARE @vDropObjects SMALLINT = 1; 85 | IF @vDropObjects = 1 86 | BEGIN 87 | DROP TABLE IF EXISTS dbo.tbl_example_13; 88 | DROP SYNONYM IF EXISTS dbo.syn_invalid_example_13; 89 | DROP SYNONYM IF EXISTS dbo.syn_example_13; 90 | DROP VIEW IF EXISTS dbo.vw_example_13; 91 | DROP PROCEDURE IF EXISTS dbo.sp_example_13; 92 | END; 93 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/14_Triggers_DML.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_14; 6 | DROP TRIGGER IF EXISTS dbo.trg_example_14; 7 | GO 8 | 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE TABLE dbo.tbl_example_14 16 | ( 17 | OrderID INT, 18 | ProductID INT, 19 | Quantity INT, 20 | UnitPrice MONEY 21 | ); 22 | GO 23 | 24 | CREATE TRIGGER dbo.trg_example_14 ON dbo.tbl_example_14 25 | AFTER INSERT, UPDATE, DELETE 26 | AS 27 | BEGIN 28 | SELECT * FROM inserted; 29 | SELECT * FROM deleted; 30 | END; 31 | GO 32 | 33 | ------------------------------------------------------- 34 | ------------------------------------------------------- 35 | ------------------------------------------------------- 36 | USE foo; 37 | GO 38 | 39 | DECLARE @vTruncate SMALLINT = 0; 40 | IF @vTruncate = 1 41 | BEGIN 42 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 43 | END; 44 | GO 45 | ------------------------------------------------------- 46 | USE foo; 47 | GO 48 | 49 | INSERT INTO foo.dbo.sql_expression_dependencies 50 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 51 | SELECT '14', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 52 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 53 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 54 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 55 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 56 | sys.server_triggers e ON a.referencing_id = e.object_id; 57 | GO 58 | 59 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 60 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 61 | FROM sys.objects 62 | GO 63 | 64 | ------------------------------------------------------- 65 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 66 | GO 67 | 68 | --------------------------------------------- 69 | USE foo; 70 | GO 71 | 72 | DECLARE @vDropObjects SMALLINT = 1; 73 | IF @vDropObjects = 1 74 | BEGIN 75 | DROP TABLE IF EXISTS dbo.tbl_example_14; 76 | DROP TRIGGER IF EXISTS dbo.trg_example_14; 77 | END; 78 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/18_Defaults_and_Rules.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_18; 6 | DROP DEFAULT IF EXISTS dbo.default_example_18; 7 | DROP RULE IF EXISTS dbo.rule_example_18; 8 | GO 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE TABLE dbo.tbl_example_18 16 | ( 17 | OrderID INT, 18 | ProductID INT, 19 | Quantity INT, 20 | UnitPrice MONEY, 21 | PhoneNumber VARCHAR(20) 22 | ); 23 | GO 24 | 25 | CREATE DEFAULT dbo.default_example_18 AS 'Unknown'; 26 | GO 27 | 28 | CREATE RULE dbo.rule_example_18 AS 29 | (@phone = 'Unknown') OR 30 | ( 31 | LEN(@phone) = 14 AND 32 | SUBSTRING(@phone, 1, 1) = '/' AND 33 | SUBSTRING(@phone, 4, 1) = '/' 34 | ); 35 | GO 36 | 37 | -- Bind the default to the column 38 | EXEC sp_bindefault 'dbo.default_example_18', 'dbo.tbl_example_18.PhoneNumber'; 39 | GO 40 | 41 | -- Bind the rule to the column 42 | EXEC sp_bindrule 'dbo.rule_example_18', 'dbo.tbl_example_18.PhoneNumber'; 43 | GO 44 | 45 | ------------------------------------------------------- 46 | ------------------------------------------------------- 47 | ------------------------------------------------------- 48 | USE foo; 49 | GO 50 | 51 | DECLARE @vTruncate SMALLINT = 0; 52 | IF @vTruncate = 1 53 | BEGIN 54 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 55 | END; 56 | GO 57 | ------------------------------------------------------- 58 | USE foo; 59 | GO 60 | 61 | INSERT INTO foo.dbo.sql_expression_dependencies 62 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 63 | SELECT '18', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 64 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 65 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 66 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 67 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 68 | sys.server_triggers e ON a.referencing_id = e.object_id; 69 | GO 70 | 71 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 72 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 73 | FROM sys.objects 74 | GO 75 | 76 | ------------------------------------------------------- 77 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 78 | GO 79 | 80 | --------------------------------------------- 81 | USE foo 82 | GO 83 | 84 | DECLARE @vDropObjects SMALLINT = 1; 85 | IF @vDropObjects = 1 86 | BEGIN 87 | DROP TABLE IF EXISTS dbo.tbl_example_18; 88 | DROP DEFAULT IF EXISTS dbo.default_example_18; 89 | DROP RULE IF EXISTS dbo.rule_example_18; 90 | END; 91 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/20_Sequences.sql: -------------------------------------------------------------------------------- 1 | ------------------------ 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS tbl_example_20; 6 | DROP PROCEDURE IF EXISTS dbo.sp_example_20; 7 | DROP SEQUENCE IF EXISTS sequence_example_20; 8 | GO 9 | 10 | ------------------------ 11 | USE foo; 12 | GO 13 | 14 | CREATE SEQUENCE sequence_example_20 15 | START WITH 1 16 | INCREMENT BY 1; 17 | GO 18 | 19 | CREATE TABLE tbl_example_20 20 | ( 21 | ID INT DEFAULT NEXT VALUE FOR sequence_example_20 22 | ); 23 | GO 24 | 25 | CREATE PROCEDURE dbo.sp_example_20 26 | AS 27 | BEGIN 28 | DECLARE @nextSeqValue BIGINT; 29 | 30 | SET @nextSeqValue = NEXT VALUE FOR sequence_example_20; 31 | 32 | INSERT INTO tbl_example_20 (ID) 33 | VALUES (@nextSeqValue) 34 | END; 35 | GO 36 | 37 | ------------------------------------------------------- 38 | ------------------------------------------------------- 39 | ------------------------------------------------------- 40 | USE foo; 41 | GO 42 | 43 | DECLARE @vTruncate SMALLINT = 0; 44 | IF @vTruncate = 1 45 | BEGIN 46 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 47 | END; 48 | GO 49 | 50 | ------------------------------------------------------- 51 | USE foo; 52 | GO 53 | 54 | INSERT INTO foo.dbo.sql_expression_dependencies 55 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 56 | SELECT '20', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 57 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 58 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 59 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 60 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 61 | sys.server_triggers e ON a.referencing_id = e.object_id; 62 | GO 63 | 64 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 65 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 66 | FROM sys.objects 67 | GO 68 | 69 | ------------------------------------------------------- 70 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 71 | GO 72 | 73 | --------------------------------------------- 74 | USE foo; 75 | GO 76 | 77 | DECLARE @vDropObjects SMALLINT = 1; 78 | IF @vDropObjects = 1 79 | BEGIN 80 | DROP TABLE IF EXISTS tbl_example_20; 81 | DROP PROCEDURE IF EXISTS dbo.sp_example_20; 82 | DROP SEQUENCE IF EXISTS sequence_example_20; 83 | END; 84 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/21_User_Defined_Data_Types.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_21; 6 | DROP PROCEDURE IF EXISTS dbo.sp_example_21; 7 | DROP TYPE IF EXISTS dbo.uddt_example_21; 8 | GO 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE TYPE dbo.uddt_example_21 FROM VARCHAR(255) NOT NULL; 16 | GO 17 | 18 | CREATE TABLE dbo.tbl_example_21 19 | ( 20 | OrderID INT, 21 | ProductID INT, 22 | Quantity INT, 23 | UnitPrice MONEY, 24 | UddtExample dbo.uddt_example_21 25 | ); 26 | GO 27 | 28 | CREATE PROCEDURE dbo.sp_example_21 AS 29 | BEGIN 30 | DECLARE @vMyVarchar AS dbo.uddt_example_21 31 | END; 32 | GO 33 | 34 | ------------------------------------------------------- 35 | ------------------------------------------------------- 36 | ------------------------------------------------------- 37 | USE foo; 38 | GO 39 | 40 | DECLARE @vTruncate SMALLINT = 0; 41 | IF @vTruncate = 1 42 | BEGIN 43 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 44 | END; 45 | GO 46 | ------------------------------------------------------- 47 | USE foo; 48 | GO 49 | 50 | INSERT INTO foo.dbo.sql_expression_dependencies 51 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 52 | SELECT '21', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 53 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 54 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 55 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 56 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 57 | sys.server_triggers e ON a.referencing_id = e.object_id; 58 | GO 59 | 60 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 61 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 62 | FROM sys.objects 63 | UNION ALL 64 | SELECT 'sys.types', user_type_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, NULL, schema_id, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL 65 | FROM sys.types 66 | WHERE is_user_defined = 1; 67 | GO 68 | 69 | ------------------------------------------------------- 70 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 71 | GO 72 | 73 | --------------------------------------------- 74 | USE foo; 75 | GO 76 | 77 | DECLARE @vDropObjects SMALLINT = 1; 78 | IF @vDropObjects = 1 79 | BEGIN 80 | DROP TABLE IF EXISTS dbo.tbl_example_21; 81 | DROP PROCEDURE IF EXISTS dbo.sp_example_21; 82 | DROP TYPE IF EXISTS dbo.uddt_example_21; 83 | END; 84 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/22_User_Defined_Table_Types.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP PROCEDURE IF EXISTS dbo.sp_example_22; 6 | DROP TYPE IF EXISTS dbo.udtt_example_22; 7 | GO 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | USE foo; 12 | GO 13 | 14 | CREATE TYPE dbo.udtt_example_22 AS TABLE 15 | ( 16 | OrderID INT, 17 | ProductID INT, 18 | Quantity INT, 19 | UnitPrice MONEY 20 | ); 21 | GO 22 | 23 | CREATE PROCEDURE dbo.sp_example_22 AS 24 | BEGIN 25 | DECLARE @vMyVariable AS dbo.udtt_example_22; 26 | END; 27 | GO 28 | 29 | ------------------------------------------------------- 30 | ------------------------------------------------------- 31 | ------------------------------------------------------- 32 | USE foo; 33 | GO 34 | 35 | DECLARE @vTruncate SMALLINT = 0; 36 | IF @vTruncate = 1 37 | BEGIN 38 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 39 | END; 40 | GO 41 | ------------------------------------------------------- 42 | USE foo; 43 | GO 44 | 45 | INSERT INTO foo.dbo.sql_expression_dependencies 46 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 47 | SELECT '22', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 48 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 49 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 50 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 51 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 52 | sys.server_triggers e ON a.referencing_id = e.object_id; 53 | GO 54 | 55 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 56 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 57 | FROM sys.objects 58 | UNION ALL 59 | SELECT 'sys.types', user_type_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, NULL, schema_id, NULL, NULL, NULL, NULL, NULL, NULL, NULL, NULL 60 | FROM sys.types 61 | WHERE is_user_defined = 1; 62 | GO 63 | 64 | ------------------------------------------------------- 65 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 66 | GO 67 | 68 | --------------------------------------------- 69 | USE foo; 70 | GO 71 | 72 | DECLARE @vDropObjects SMALLINT = 1; 73 | IF @vDropObjects = 1 74 | BEGIN 75 | DROP PROCEDURE IF EXISTS dbo.sp_example_22; 76 | DROP TYPE IF EXISTS dbo.udtt_example_22; 77 | END; 78 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/23_Check_Constraints.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | 6 | DROP TABLE IF EXISTS dbo.tbl_example_23; 7 | DROP FUNCTION IF EXISTS dbo.fn_example_23; 8 | GO 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE FUNCTION dbo.fn_example_23 (@vQuantity INT) RETURNS VARCHAR(22) AS 16 | BEGIN 17 | DECLARE @result VARCHAR(10); 18 | IF @vQuantity >= 1 19 | SET @result = 'TRUE'; 20 | ELSE 21 | SET @result = 'FALSE'; 22 | RETURN @result 23 | END; 24 | GO 25 | 26 | CREATE TABLE dbo.tbl_example_23 27 | ( 28 | OrderID INT, 29 | ProductID INT, 30 | Quantity INT, 31 | UnitPrice MONEY, 32 | CONSTRAINT example_23_chk_id CHECK (OrderID <> ProductID), 33 | CONSTRAINT example_23_chk_quantity CHECK (dbo.fn_example_23(Quantity) = 'TRUE') 34 | ); 35 | GO 36 | 37 | ------------------------------------------------------- 38 | ------------------------------------------------------- 39 | ------------------------------------------------------- 40 | USE foo; 41 | GO 42 | 43 | DECLARE @vTruncate SMALLINT = 0; 44 | IF @vTruncate = 1 45 | BEGIN 46 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 47 | END; 48 | GO 49 | 50 | ------------------------------------------------------- 51 | USE foo; 52 | GO 53 | 54 | INSERT INTO foo.dbo.sql_expression_dependencies 55 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 56 | SELECT '23', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 57 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 58 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 59 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 60 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 61 | sys.server_triggers e ON a.referencing_id = e.object_id; 62 | GO 63 | 64 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 65 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 66 | FROM sys.objects 67 | GO 68 | 69 | ------------------------------------------------------- 70 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 71 | GO 72 | --------------------------------------------- 73 | USE foo; 74 | GO 75 | 76 | DECLARE @vDropObjects SMALLINT = 1; 77 | IF @vDropObjects = 1 78 | BEGIN 79 | DROP TABLE IF EXISTS dbo.tbl_example_23; 80 | DROP FUNCTION IF EXISTS dbo.fn_example_23; 81 | END; 82 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/24_Foreign_Key_Constraints.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_24_child; 6 | DROP TABLE IF EXISTS tbl_example_24_parent; 7 | GO 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | USE foo; 12 | GO 13 | 14 | CREATE TABLE tbl_example_24_parent 15 | ( 16 | ParentID INT PRIMARY KEY, -- Primary Key in parent table 17 | ParentName VARCHAR(100) NOT NULL 18 | ); 19 | GO 20 | 21 | CREATE TABLE tbl_example_24_child 22 | ( 23 | ChildID INT PRIMARY KEY, -- Primary Key in child table 24 | ChildName NVARCHAR(100) NOT NULL, 25 | ParentID INT, -- Foreign Key column referencing ParentID in parent table 26 | CONSTRAINT FK_Child_Parent FOREIGN KEY (ParentID) 27 | REFERENCES tbl_example_24_parent(ParentID) -- Foreign Key constraint 28 | ); 29 | GO 30 | 31 | ------------------------------------------------------- 32 | ------------------------------------------------------- 33 | ------------------------------------------------------- 34 | USE foo; 35 | GO 36 | 37 | DECLARE @vTruncate SMALLINT = 0; 38 | IF @vTruncate = 1 39 | BEGIN 40 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 41 | END; 42 | GO 43 | 44 | ------------------------------------------------------- 45 | USE foo; 46 | GO 47 | 48 | INSERT INTO foo.dbo.sql_expression_dependencies 49 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 50 | SELECT '24', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 51 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 52 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 53 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 54 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 55 | sys.server_triggers e ON a.referencing_id = e.object_id; 56 | GO 57 | 58 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 59 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 60 | FROM sys.objects 61 | GO 62 | ------------------------------------------------------- 63 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 64 | GO 65 | 66 | --------------------------------------------- 67 | USE foo; 68 | GO 69 | 70 | DECLARE @vDropObjects SMALLINT = 1; 71 | IF @vDropObjects = 1 72 | BEGIN 73 | DROP TABLE IF EXISTS dbo.tbl_example_24_child; 74 | DROP TABLE IF EXISTS tbl_example_24_parent; 75 | END; 76 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/25_Computed_Columns.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_25; 6 | DROP FUNCTION IF EXISTS dbo.fn_example_25; 7 | GO 8 | 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE FUNCTION dbo.fn_example_25 (@vUnitPrice MONEY, @vQuantity INT) RETURNS MONEY AS 16 | BEGIN 17 | RETURN @vUnitPrice * @vQuantity; 18 | END; 19 | GO 20 | 21 | CREATE TABLE dbo.tbl_example_25 22 | ( 23 | OrderID INT, 24 | ProductID INT, 25 | Quantity INT, 26 | UnitPrice MONEY, 27 | TotalValue AS (UnitPrice * Quantity), 28 | TotalValue2 AS (dbo.fn_example_25(UnitPrice,Quantity)) 29 | ); 30 | GO 31 | 32 | ------------------------------------------------------- 33 | ------------------------------------------------------- 34 | ------------------------------------------------------- 35 | USE foo; 36 | GO 37 | 38 | DECLARE @vTruncate SMALLINT = 0; 39 | IF @vTruncate = 1 40 | BEGIN 41 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 42 | END; 43 | GO 44 | 45 | ------------------------------------------------------- 46 | USE foo; 47 | GO 48 | 49 | INSERT INTO foo.dbo.sql_expression_dependencies 50 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 51 | SELECT '25', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 52 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 53 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 54 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 55 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 56 | sys.server_triggers e ON a.referencing_id = e.object_id; 57 | GO 58 | 59 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 60 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 61 | FROM sys.objects 62 | GO 63 | 64 | ------------------------------------------------------- 65 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 66 | GO 67 | 68 | --------------------------------------------- 69 | USE foo; 70 | GO 71 | 72 | DECLARE @vDropObjects SMALLINT = 1; 73 | IF @vDropObjects = 1 74 | BEGIN 75 | DROP TABLE IF EXISTS dbo.tbl_example_25; 76 | DROP FUNCTION IF EXISTS dbo.fn_example_25; 77 | END; 78 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/26_Masked_Functions.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_26; 6 | GO 7 | 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | USE foo; 12 | GO 13 | 14 | CREATE TABLE dbo.tbl_example_26 15 | ( 16 | EmployeeID INT IDENTITY(1,1) PRIMARY KEY, 17 | FirstName VARCHAR(50) MASKED WITH (FUNCTION = 'default()'), -- Default mask: masks the entire value based on the data type 18 | LastName VARCHAR(50) MASKED WITH (FUNCTION = 'partial(1,"XXXXXX",1)'), -- Partial mask: shows first and last character only 19 | Email VARCHAR(255) MASKED WITH (FUNCTION = 'email()'), -- Email mask: hides part of the email 20 | PhoneNumber VARCHAR(15) MASKED WITH (FUNCTION = 'partial(0, "XXX-XXX-", 4)'), -- Partial mask for phone number 21 | Salary INT MASKED WITH (FUNCTION = 'random(1000, 5000)') -- Random mask: generates a random number in the specified range 22 | ); 23 | GO 24 | 25 | ------------------------------------------------------- 26 | ------------------------------------------------------- 27 | ------------------------------------------------------- 28 | USE foo; 29 | GO 30 | 31 | DECLARE @vTruncate SMALLINT = 0; 32 | IF @vTruncate = 1 33 | BEGIN 34 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 35 | END; 36 | GO 37 | 38 | ------------------------------------------------------- 39 | USE foo; 40 | GO 41 | 42 | INSERT INTO foo.dbo.sql_expression_dependencies 43 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 44 | SELECT '26', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 45 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 46 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 47 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 48 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 49 | sys.server_triggers e ON a.referencing_id = e.object_id; 50 | GO 51 | 52 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 53 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 54 | FROM sys.objects 55 | GO 56 | 57 | ------------------------------------------------------- 58 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 59 | GO 60 | 61 | ------------------------------------------------------- 62 | USE foo; 63 | GO 64 | 65 | DECLARE @vDropObjects SMALLINT = 1; 66 | IF @vDropObjects = 1 67 | BEGIN 68 | DROP TABLE IF EXISTS dbo.tbl_example_26; 69 | END; 70 | GO 71 | -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/27_Indexes_Table.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | 6 | DROP TABLE IF EXISTS dbo.tbl_example_27; 7 | DROP TABLE IF EXISTS dbo.tbl_example_xml_27; 8 | GO 9 | 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | --------------------------------------------- 13 | USE foo; 14 | GO 15 | 16 | CREATE TABLE dbo.tbl_example_27 17 | ( 18 | OrderID INT PRIMARY KEY, 19 | ProductID INT, 20 | Quantity INT, 21 | UnitPrice MONEY 22 | ); 23 | GO 24 | 25 | CREATE NONCLUSTERED INDEX idx_nonclustered_example_27 26 | ON dbo.tbl_example_27 (ProductID); 27 | GO 28 | 29 | --The statement failed. Column 'OrderCatalog' has a data type that cannot participate in a columnstore index. 30 | CREATE NONCLUSTERED COLUMNSTORE INDEX idx_nonclustered_columnstore_example_27 31 | ON dbo.tbl_example_27 (UnitPrice); 32 | GO 33 | 34 | --------------------------------------------- 35 | 36 | CREATE TABLE dbo.tbl_example_xml_27 37 | ( 38 | OrderID INT PRIMARY KEY, 39 | ProductID INT, 40 | Quantity INT, 41 | UnitPrice MONEY, 42 | OrderCatalog XML 43 | ); 44 | GO 45 | 46 | CREATE PRIMARY XML INDEX idx_xml_example_27 47 | ON dbo.tbl_example_xml_27 (OrderCatalog); 48 | GO 49 | 50 | CREATE XML INDEX idx_xml_example_27_a 51 | ON dbo.tbl_example_xml_27 (OrderCatalog) 52 | USING XML INDEX idx_xml_example_27 53 | FOR PATH; 54 | GO 55 | 56 | CREATE XML INDEX idx_xml_example_27_b 57 | ON dbo.tbl_example_xml_27 (OrderCatalog) 58 | USING XML INDEX idx_xml_example_27 59 | FOR VALUE; 60 | GO 61 | 62 | ------------------------------------------------------- 63 | ------------------------------------------------------- 64 | ------------------------------------------------------- 65 | USE foo; 66 | GO 67 | 68 | DECLARE @vTruncate SMALLINT = 0; 69 | IF @vTruncate = 1 70 | BEGIN 71 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 72 | END; 73 | GO 74 | 75 | ------------------------------------------------------- 76 | USE foo; 77 | GO 78 | 79 | INSERT INTO foo.dbo.sql_expression_dependencies 80 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 81 | SELECT '27', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 82 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 83 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 84 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 85 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 86 | sys.server_triggers e ON a.referencing_id = e.object_id; 87 | GO 88 | 89 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 90 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 91 | FROM sys.objects 92 | GO 93 | 94 | ------------------------------------------------------- 95 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 96 | GO 97 | 98 | --------------------------------------------- 99 | USE foo; 100 | GO 101 | 102 | DECLARE @vDropObjects SMALLINT = 1; 103 | IF @vDropObjects = 1 104 | BEGIN 105 | DROP TABLE IF EXISTS dbo.tbl_example_27; 106 | DROP TABLE IF EXISTS dbo.tbl_example_xml_27; 107 | END; 108 | GO 109 | -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/28_Indexes_Filtered_NonClustered.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_28; 6 | GO 7 | --------------------------------------------- 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | USE foo; 11 | GO 12 | 13 | CREATE TABLE dbo.tbl_example_28 14 | ( 15 | OrderID INT, 16 | ProductID INT, 17 | Quantity INT, 18 | UnitPrice MONEY, 19 | OrderCatalog XML 20 | ); 21 | GO 22 | 23 | CREATE NONCLUSTERED INDEX idx_example_28 ON dbo.tbl_example_28 (OrderID ASC) 24 | WHERE (ProductID=(1)); 25 | GO 26 | 27 | ------------------------------------------------------- 28 | ------------------------------------------------------- 29 | ------------------------------------------------------- 30 | USE foo; 31 | GO 32 | 33 | DECLARE @vTruncate SMALLINT = 0; 34 | IF @vTruncate = 1 35 | BEGIN 36 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 37 | END; 38 | GO 39 | 40 | ------------------------------------------------------- 41 | USE foo; 42 | GO 43 | 44 | INSERT INTO foo.dbo.sql_expression_dependencies 45 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 46 | SELECT '28', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 47 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 48 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 49 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 50 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 51 | sys.server_triggers e ON a.referencing_id = e.object_id; 52 | GO 53 | 54 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 55 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 56 | FROM sys.objects 57 | GO 58 | 59 | ------------------------------------------------------- 60 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 61 | GO 62 | 63 | --------------------------------------------- 64 | USE foo; 65 | GO 66 | 67 | DECLARE @vDropObjects SMALLINT = 1; 68 | IF @vDropObjects = 1 69 | BEGIN 70 | DROP TABLE IF EXISTS dbo.tbl_example_28; 71 | END; 72 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/29_Indexes_Filtered_XML.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP TABLE IF EXISTS dbo.tbl_example_29; 6 | GO 7 | 8 | --------------------------------------------- 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | USE foo; 12 | GO 13 | 14 | CREATE TABLE dbo.tbl_example_29 15 | ( 16 | OrderID INT PRIMARY KEY, 17 | ProductID INT, 18 | Quantity INT, 19 | UnitPrice MONEY, 20 | OrderCatalog XML 21 | ); 22 | GO 23 | 24 | CREATE NONCLUSTERED INDEX idx_example_29 25 | ON dbo.tbl_example_29 (ProductID) 26 | WHERE ProductID = 1; 27 | GO 28 | 29 | ------------------------------------------------------- 30 | ------------------------------------------------------- 31 | ------------------------------------------------------- 32 | USE foo; 33 | GO 34 | 35 | DECLARE @vTruncate SMALLINT = 0; 36 | IF @vTruncate = 1 37 | BEGIN 38 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 39 | END; 40 | GO 41 | 42 | ------------------------------------------------------- 43 | USE foo; 44 | GO 45 | 46 | INSERT INTO foo.dbo.sql_expression_dependencies 47 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 48 | SELECT '29', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 49 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 50 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 51 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 52 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 53 | sys.server_triggers e ON a.referencing_id = e.object_id; 54 | GO 55 | 56 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 57 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 58 | FROM sys.objects 59 | GO 60 | 61 | ------------------------------------------------------- 62 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 63 | GO 64 | 65 | --------------------------------------------- 66 | USE foo; 67 | GO 68 | 69 | DECLARE @vDropObjects SMALLINT = 1; 70 | IF @vDropObjects = 1 71 | BEGIN 72 | DROP PROCEDURE IF EXISTS dbo.sp_example_29; 73 | DROP TABLE IF EXISTS dbo.tbl_example_29; 74 | END; 75 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/30_Statistics_Filtered.sql: -------------------------------------------------------------------------------- 1 | USE foo; 2 | GO 3 | 4 | IF EXISTS ( 5 | SELECT 1 6 | FROM sys.stats AS s INNER JOIN 7 | sys.objects AS o ON s.object_id = o.object_id 8 | WHERE o.name = 'tbl_example_30' AND 9 | s.name = 'stat_example_30' 10 | ) 11 | BEGIN 12 | DROP STATISTICS dbo.tbl_example_30.stat_example_30; 13 | END 14 | GO 15 | 16 | DROP TABLE IF EXISTS dbo.tbl_example_30; 17 | GO 18 | 19 | ------------------------------------------------------- 20 | ------------------------------------------------------- 21 | ------------------------------------------------------- 22 | USE foo; 23 | GO 24 | 25 | CREATE TABLE dbo.tbl_example_30 26 | ( 27 | OrderID INT, 28 | ProductID INT, 29 | Quantity INT, 30 | UnitPrice MONEY 31 | ); 32 | GO 33 | 34 | -- Create a filtered statistic for rows where Quantity is greater than 100 35 | CREATE STATISTICS stat_example_30 ON dbo.tbl_example_30 (UnitPrice) 36 | WHERE Quantity > 100; 37 | GO 38 | 39 | ------------------------------------------------------- 40 | ------------------------------------------------------- 41 | ------------------------------------------------------- 42 | USE foo; 43 | GO 44 | 45 | DECLARE @vTruncate SMALLINT = 0; 46 | IF @vTruncate = 1 47 | BEGIN 48 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 49 | END; 50 | GO 51 | 52 | ------------------------------------------------------- 53 | USE foo; 54 | GO 55 | 56 | INSERT INTO foo.dbo.sql_expression_dependencies 57 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 58 | SELECT '30', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 59 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 60 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 61 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 62 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 63 | sys.server_triggers e ON a.referencing_id = e.object_id; 64 | GO 65 | 66 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 67 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 68 | FROM sys.objects 69 | GO 70 | 71 | ------------------------------------------------------- 72 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 73 | GO 74 | 75 | ------------------------------------------------------- 76 | USE foo; 77 | GO 78 | 79 | DECLARE @vDropObjects SMALLINT = 1; 80 | IF EXISTS (SELECT 1 FROM sys.stats AS s WHERE name = 'stat_example_30') AND @vDropObjects = 1 81 | BEGIN 82 | DROP STATISTICS dbo.tbl_example_30.stat_example_30; 83 | END 84 | GO 85 | 86 | DECLARE @vDropObjects SMALLINT = 1; 87 | IF @vDropObjects = 1 88 | BEGIN 89 | DROP TABLE IF EXISTS dbo.tbl_example_30; 90 | END; 91 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/32_XML_Methods.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------- 2 | USE foo; 3 | GO 4 | 5 | DROP PROCEDURE IF EXISTS dbo.sp_example_32; 6 | DROP TABLE IF EXISTS dbo.tbl_example_32; 7 | GO 8 | 9 | --------------------------------------------- 10 | --------------------------------------------- 11 | --------------------------------------------- 12 | USE foo; 13 | GO 14 | 15 | CREATE TABLE dbo.tbl_example_32 16 | ( 17 | ID INT, 18 | column_xml_example_32 XML 19 | ); 20 | GO 21 | 22 | INSERT INTO dbo.tbl_example_32 (Id, column_xml_example_32) VALUES (1, 'Hello World'); 23 | GO 24 | 25 | CREATE PROCEDURE dbo.sp_example_32 AS 26 | BEGIN 27 | 28 | -- value() 29 | SELECT t.column_xml_example_32.value('(./Record/@id)[1]', 'int') 30 | FROM dbo.tbl_example_32 t; 31 | 32 | -- exist() 33 | SELECT t.column_xml_example_32.exist('/Record[Message = "Hello World"]') 34 | FROM dbo.tbl_example_32 t; 35 | 36 | -- query() 37 | SELECT t.column_xml_example_32.query('/Record/Message') 38 | FROM dbo.tbl_example_32 t; 39 | 40 | -- nodes() 41 | SELECT x.n.value('(text())[1]', 'NVARCHAR(100)') 42 | FROM dbo.tbl_example_32 t CROSS APPLY 43 | t.column_xml_example_32.nodes('/Record/Message') AS x(n); 44 | 45 | -- modify() 46 | UPDATE dbo.tbl_example_32 47 | SET column_xml_example_32.modify('replace value of (/Record/Message/text())[1] with "Goodbye World"') 48 | WHERE Id = 1; 49 | 50 | END; 51 | GO 52 | 53 | ------------------------------------------------------- 54 | ------------------------------------------------------- 55 | ------------------------------------------------------- 56 | USE foo; 57 | GO 58 | 59 | DECLARE @vTruncate SMALLINT = 0; 60 | IF @vTruncate = 1 61 | BEGIN 62 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 63 | END; 64 | GO 65 | 66 | ------------------------------------------------------- 67 | USE foo; 68 | GO 69 | 70 | INSERT INTO foo.dbo.sql_expression_dependencies 71 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 72 | SELECT '32', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 73 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 74 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 75 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 76 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 77 | sys.server_triggers e ON a.referencing_id = e.object_id; 78 | GO 79 | 80 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 81 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 82 | FROM sys.objects 83 | GO 84 | 85 | ------------------------------------------------------- 86 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 87 | GO 88 | 89 | --------------------------------------------- 90 | USE foo; 91 | GO 92 | 93 | DECLARE @vDropObjects SMALLINT = 1; 94 | IF @vDropObjects = 1 95 | BEGIN 96 | DROP PROCEDURE IF EXISTS dbo.sp_example_32; 97 | DROP TABLE IF EXISTS dbo.tbl_example_32; 98 | END; 99 | GO -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/Additional SQL Scripts/01_Create_Databases_Schemas_Tables.sql: -------------------------------------------------------------------------------- 1 | USE master; 2 | GO 3 | 4 | ---------------------------------------- 5 | DROP TRIGGER IF EXISTS trg_example_16 ON ALL SERVER; 6 | GO 7 | DROP DATABASE IF EXISTS db_example_16; 8 | GO 9 | 10 | ---------------------------------------- 11 | DROP DATABASE IF EXISTS foo; 12 | DROP DATABASE IF EXISTS bar; 13 | GO 14 | 15 | ---------------------------------------- 16 | CREATE DATABASE foo; 17 | GO 18 | CREATE DATABASE bar; 19 | GO 20 | 21 | ---------------------------------------- 22 | USE foo; 23 | GO 24 | 25 | CREATE SCHEMA schemaA; 26 | GO 27 | CREATE SCHEMA schemaB; 28 | GO 29 | 30 | ---------------------------------------- 31 | USE foo; 32 | GO 33 | 34 | DROP TABLE IF EXISTS dbo.sql_expression_dependencies; 35 | GO 36 | 37 | CREATE TABLE dbo.sql_expression_dependencies 38 | ( 39 | --insertdate DATETIME NOT NULL DEFAULT GETDATE(), 40 | --servername VARCHAR(100) NOT NULL, 41 | example_number VARCHAR(100) NULL, 42 | referencing_object_type VARCHAR(100) NULL, 43 | referencing_server_name VARCHAR(100) NULL, 44 | referencing_database_name VARCHAR(100) NULL, 45 | referencing_schema_name VARCHAR(100) NULL, 46 | referencing_entity_name VARCHAR(500) NULL, 47 | referencing_id INT NULL, 48 | referencing_minor_id INT NULL, 49 | referencing_class INT NULL, 50 | referencing_class_desc VARCHAR(60) NULL, 51 | is_schema_bound_reference INT NOT NULL, 52 | referenced_class INT NULL, 53 | referenced_class_desc VARCHAR(60) NULL, 54 | referenced_server_name VARCHAR(128) NULL, 55 | referenced_database_name VARCHAR(128) NULL, 56 | referenced_schema_name VARCHAR(128) NULL, 57 | referenced_entity_name VARCHAR(128) NULL, 58 | referenced_object_type VARCHAR(100) NULL, 59 | referenced_id INT NULL, 60 | referenced_minor_id INT NOT NULL, 61 | is_caller_dependent INT NOT NULL, 62 | is_ambiguous INT NOT NULL 63 | ); 64 | GO 65 | 66 | ---------------------------------------- 67 | USE foo; 68 | GO 69 | 70 | DROP TABLE IF EXISTS dbo.system_objects; 71 | GO 72 | 73 | CREATE TABLE dbo.system_objects ( 74 | table_name NVARCHAR(128) NULL, 75 | object_id INT NOT NULL, 76 | server_name NVARCHAR(128) NULL, 77 | database_name NVARCHAR(128) NOT NULL, 78 | schema_name NVARCHAR(128) NULL, 79 | name NVARCHAR(128) NULL, 80 | principal_id INT NULL, 81 | schema_id INT NULL, 82 | parent_object_id INT NULL, 83 | type VARCHAR(200) NULL, 84 | type_desc NVARCHAR(60) NULL, 85 | create_date DATETIME NULL, 86 | modify_date DATETIME NULL, 87 | is_ms_shipped BIT NULL, 88 | is_published BIT NULL, 89 | is_schema_published BIT NULL, 90 | CONSTRAINT PK_sys_objects PRIMARY KEY (object_id, database_name) WITH (IGNORE_DUP_KEY = ON) 91 | ); 92 | -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/Additional SQL Scripts/04_Kill_Open_Sessions.sql: -------------------------------------------------------------------------------- 1 | USE master; 2 | GO 3 | 4 | -- Declare variables to store session IDs 5 | DECLARE @sql NVARCHAR(MAX); 6 | DECLARE @delimiter NVARCHAR(5) = ';'; 7 | 8 | -- Build the dynamic SQL 9 | SET @sql = ( 10 | SELECT STRING_AGG('KILL ' + CAST(s.session_id AS NVARCHAR) + @delimiter, ' ') 11 | FROM sys.dm_exec_sessions s LEFT JOIN 12 | sys.dm_exec_requests r ON s.session_id = r.session_id 13 | WHERE s.is_user_process = 1 -- Only user sessions, not system sessions 14 | AND s.session_id <> @@SPID -- Exclude the current session 15 | AND r.blocking_session_id IS NULL -- Example filter: No blocking session 16 | ); 17 | 18 | -- Execute the dynamic SQL to kill sessions 19 | IF @sql IS NOT NULL AND LEN(@sql) > 0 20 | BEGIN 21 | PRINT @sql; -- Optional: Check the generated SQL before execution 22 | EXEC sp_executesql @sql; 23 | END 24 | ELSE 25 | BEGIN 26 | PRINT 'No sessions found to kill.'; 27 | END; 28 | GO 29 | 30 | 31 | /* 32 | USE master; 33 | GO 34 | 35 | SELECT 36 | s.session_id, 37 | s.host_name, 38 | s.program_name, 39 | s.login_name, 40 | r.status, 41 | r.command, 42 | r.blocking_session_id, 43 | r.wait_type, 44 | r.wait_time, 45 | r.cpu_time, 46 | r.transaction_isolation_level 47 | FROM sys.dm_exec_sessions s 48 | LEFT JOIN sys.dm_exec_requests r ON s.session_id = r.session_id 49 | WHERE s.is_user_process = 1; -- Only user sessions, not system sessions 50 | */ -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/Additional SQL Scripts/README.MD: -------------------------------------------------------------------------------- 1 | # Additional SQL Scripts 2 | 3 | This folder contains the additional scripts to create the databases, tables, and schemas, along with a deployment script and the SQL script to perform the analysis. 4 | 5 | 6 | -------------------------------------------------------------------------------- /Database Articles/Database Dependencies/SQL Scripts/README.MD: -------------------------------------------------------------------------------- 1 | # Database Dependencies SQL Scripts 2 | 3 | Here are the thirty-two scripts I used to analyze the different database dependencies that can present themselves in SQL Server. 4 | 5 | These scripts include the additional logic I used to perform the analysis, which I demonstrate below. This logic contains two boolean statements you can manipulate depending on your workflow. 6 | 7 | * `IF @vTruncate = 1` 8 | * `IF @vDropObjects = 1` 9 | 10 | One allows you to determine if you want to truncate the `foo.dbo.sql_expression_dependency` table, and the second determines if you wish to drop the created objects at the end of the script. When performing the analysis, I found it easiest to create the objects, then insert the information into the local table `foo.dbo.sql_expression_dependency` and the `foo.dbo.system_objects` table, and then lastly delete the objects. 11 | 12 | Also of note, the `foo.dbo.system_objects` table has the `IGNORE_DUP_KEY = ON`, where the primary key is `object_id` and `database_name`. Remember that `object_id` is only unique to the database, and the combination of `object_id` and `database_name` is the primary key! 13 | 14 | The scripts to create the above tables are included and located in the Additional SQL Scripts folder. 15 | 16 | Included in this folder are scripts to: 17 | 1) Create the database, schemas, and tables 18 | 2) Deploy the scripts via `sqlcmd` mode 19 | 3) A script to kill any open sessions (which I needed to perform regularly when dropping and recreating the databases in my development work). 20 | 21 | ------ 22 | 23 | Here is the additional logic that I have included in each script. 24 | 25 | ```sql 26 | USE foo; 27 | GO 28 | 29 | DECLARE @vTruncate SMALLINT = 0; 30 | IF @vTruncate = 1 31 | BEGIN 32 | TRUNCATE TABLE foo.dbo.sql_expression_dependencies; 33 | END; 34 | GO 35 | 36 | ------------------------------------------------------- 37 | USE foo; 38 | GO 39 | 40 | INSERT INTO foo.dbo.sql_expression_dependencies 41 | (example_number, referencing_object_type, referencing_server_name, referencing_database_name, referencing_schema_name, referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous) 42 | SELECT ', COALESCE(c.type, d.type, e.type) AS referencing_object_type, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(c.schema_id), COALESCE(c.name, d.name, e.name) AS referencing_entity_name, referencing_id, referencing_minor_id, referencing_class, referencing_class_desc, is_schema_bound_reference, referenced_class, referenced_class_desc, referenced_server_name, referenced_database_name, referenced_schema_name, referenced_entity_name, b.type AS referenced_object_type, referenced_id, referenced_minor_id, is_caller_dependent, is_ambiguous 43 | FROM sys.sql_expression_dependencies a LEFT OUTER JOIN 44 | sys.objects b ON a.referenced_id = b.object_id LEFT OUTER JOIN 45 | sys.objects c ON a.referencing_id = c.object_id LEFT OUTER JOIN 46 | sys.triggers d ON a.referencing_id = d.object_id LEFT OUTER JOIN 47 | sys.server_triggers e ON a.referencing_id = e.object_id; 48 | GO 49 | 50 | INSERT INTO foo.dbo.system_objects (table_name, object_id, server_name, database_name, schema_name, name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published) 51 | SELECT 'sys.objects', object_id, @@SERVERNAME, DB_NAME(), SCHEMA_NAME(schema_id), name, principal_id, schema_id, parent_object_id, type, type_desc, create_date, modify_date, is_ms_shipped, is_published, is_schema_published 52 | FROM sys.objects 53 | GO 54 | 55 | ------------------------------------------------------- 56 | SELECT * FROM foo.dbo.sql_expression_dependencies ORDER BY example_number; 57 | GO 58 | 59 | --------------------------------------------- 60 | USE foo; 61 | GO 62 | 63 | DECLARE @vDropObjects SMALLINT = 1; 64 | IF @vDropObjects = 1 65 | BEGIN 66 | DROP FUNCTION IF EXISTS dbo.fn_example_05; 67 | DROP PROCEDURE IF EXISTS dbo.sp_example_05; 68 | DROP TABLE IF EXISTS dbo.tbl_example_05; 69 | END; 70 | GO 71 | ``` 72 | 73 | 74 | 75 | 76 | 77 | 78 | 79 | 80 | -------------------------------------------------------------------------------- /Database Articles/readme.md: -------------------------------------------------------------------------------- 1 | # Database Articles 2 | 3 | This directory contains my collection of various database related writtings, and a few Azure end-to-end demos I have created. 4 | 5 | :question:      If you have any questions, please feel free to create a GitHub discussion. I am always happy to help out and explain different solutions. 6 | 7 | ⌨️      All SQL is written in Microsoft SQL Server T-SQL unless otherwise noted. 8 | 9 | ## Getting Started 10 | 11 | The items in this directory can be grouped into two categories: 12 | 13 | :point_right:   **Database Writings** 14 | * Advanced SQL Joins 15 | * Behavior of Nulls 16 | 17 | :point_right:   **Azure Demos** 18 | * Azure Databricks Hive Demo 19 | * Azure Data Factory Metadata Demo 20 | ---------------- 21 | 22 | :mailbox:      If you find any inaccuracies, misspellings, bugs, dead links, etc... please report an issue! No detail is too small, and I appreciate all the help. 23 | 24 | :smile:      Happy coding! 25 | 26 | I hope you find this repository to be useful and informative, and I welcome any new puzzles or tips and tricks you may have. I also have a WordPress site where you can find my data analytics projects, Python puzzles, and blog. 27 | 28 | https://advancedsqlpuzzles.com 29 | 30 | -------------------------------------------------------------------------------- /readme.md: -------------------------------------------------------------------------------- 1 | # Advanced SQL Puzzles 2 | 3 | This repository contains a collection of my SQL puzzles and various writings. Feel free to rummage around, I am constantly updating this repository, so check back often. 4 | 5 | :keyboard:      All SQL is written in Microsoft SQL Server T-SQL, unless otherwise noted. 6 | 7 | :star:      Please consider giving a star to this repository if you find its contents informative! 8 | 9 | :question:      If you have any questions, please feel free to create a GitHub discussion. I am always happy to help out and explain different solutions. 10 | 11 | ## Getting Started 12 | 13 | To get started, clone or download the repository to your local machine. I have included readme files for each directory that describes its contents. If anything is unclear, please contact me, and I would be happy to assist. 14 | 15 | ## About Me 16 | 17 | Greetings. I am Scott Peters, a resident of Austin, TX. I am always eager to collaborate with fellow SQL developers. I've probably written the word `SELECT` two hundred thousand times. If you would like to connect, please drop me a line. 18 | 19 | ## Conclusion 20 | 21 | :mailbox:      If you find any inaccuracies, misspellings, bugs, dead links, etc., please report an issue! No detail is too small, and I appreciate all the help. 22 | 23 | :smile:      Happy coding! 24 | 25 | I hope you find this repository useful and informative, and I welcome any new puzzles or tips and tricks you may have. I also have a WordPress site where you can find my data analytics projects, Python puzzles, and blog. 26 | 27 | **https://advancedsqlpuzzles.com** 28 | --------------------------------------------------------------------------------