diff --git a/9781430245964.jpg b/9781430245964.jpg new file mode 100644 index 0000000..400a66c Binary files /dev/null and b/9781430245964.jpg differ diff --git a/LICENSE.txt b/LICENSE.txt new file mode 100644 index 0000000..aee39f2 --- /dev/null +++ b/LICENSE.txt @@ -0,0 +1,27 @@ +Freeware License, some rights reserved + +Copyright (c) 2012 Michael Coles, Scott Shaw, Jay Natarajan, and Rudi Bruchez + +Permission is hereby granted, free of charge, to anyone obtaining a copy +of this software and associated documentation files (the "Software"), +to work with the Software within the limits of freeware distribution and fair use. +This includes the rights to use, copy, and modify the Software for personal use. +Users are also allowed and encouraged to submit corrections and modifications +to the Software for the benefit of other users. + +It is not allowed to reuse, modify, or redistribute the Software for +commercial use in any way, or for a user’s educational materials such as books +or blog articles without prior permission from the copyright holder. + +The above copyright notice and this permission notice need to be included +in all copies or substantial portions of the software. + +THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR +IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, +FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE +AUTHORS OR COPYRIGHT HOLDERS OR APRESS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER +LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, +OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE +SOFTWARE. + + diff --git a/Pro T-SQL 2012 Programmer's Guide/9781430245964_Scripts.docx b/Pro T-SQL 2012 Programmer's Guide/9781430245964_Scripts.docx new file mode 100644 index 0000000..41fc5bb Binary files /dev/null and b/Pro T-SQL 2012 Programmer's Guide/9781430245964_Scripts.docx differ diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch05/9781430245964_Natarajan_Ch05_StroredProcedures.sql b/Pro T-SQL 2012 Programmer's Guide/Ch05/9781430245964_Natarajan_Ch05_StroredProcedures.sql new file mode 100644 index 0000000..6f433f9 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch05/9781430245964_Natarajan_Ch05_StroredProcedures.sql @@ -0,0 +1,618 @@ +/* Listing 5-1. Retrieving an Employee’s Name and E-mail with an SP */ +CREATE PROCEDURE Person.GetEmployee (@BusinessEntityID int = 199, +@Email_Address nvarchar(50) OUTPUT, +@Full_Name nvarchar(100) OUTPUT) +AS +BEGIN +-- Retrieve email address and full name from HumanResources.Employee table +SELECT @Email_Address = ea.EmailAddress, +@Full_Name = p.FirstName + ' ' + COALESCE(p.MiddleName,'') + ' ' + p.LastName +FROM HumanResources.Employee e +INNER JOIN Person.Person p +ON e.BusinessEntityID = p.BusinessEntityID +INNER JOIN Person.EmailAddress ea +ON p.BusinessEntityID = ea.BusinessEntityID +WHERE e.BusinessEntityID = @BusinessEntityID; +-- Return a code of 1 when no match is found, 0 for success +RETURN ( +CASE +WHEN @Email_Address IS NULL THEN 1 +ELSE 0 +END +); +END; +GO + +/* Listing 5-2. Calling the Person.GetEmployee SP */ +-- Declare variables to hold the result +DECLARE @Email nvarchar(50),@Name nvarchar(100),@Result int; +--Call procedure to get employee information +EXECUTE @Result = Person.GetEmployee 123, @Email OUTPUT, @Name OUTPUT; + +/* Listing 5-3. Retrieving a Contact’s ID, Name, Title, and DOB with an SP */ +CREATE PROCEDURE Person.GetContactDetails (@ID int) +AS +BEGIN +SET NOCOUNT ON +-- Retrieve Name and title for a given PersonID +SELECT @ID, p.FirstName + ' ' + COALESCE(p.MiddleName,'') + ' ' + p.LastName, ct.[Name], +cast(p.ModifiedDate as varchar(20)), 'Vendor Contact' +FROM [Purchasing].[Vendor] AS v +INNER JOIN [Person].[BusinessEntityContact] bec +ON bec.[BusinessEntityID] = v.[BusinessEntityID] +INNER JOIN [Person].ContactType ct +ON ct.[ContactTypeID] = bec.[ContactTypeID] +INNER JOIN [Person].[Person] p +ON p.[BusinessEntityID] = bec.[PersonID] +WHERE bec.[PersonID] = @ID; +END; +GO + +/*Listing 5-4. Calling the Person.GetContactDetails SP */ +-- Declare variables to hold the result +DECLARE @ContactID int; +SET @ContactID = 1511; +--Call procedure to get consumer information +EXEC dbo.GetContactDetails @ContactID with result sets( +( +ContactID int,--Column Name changed +ContactName varchar(200),--Column Name changed +Title varchar(50),--Column Name changed +LastUpdatedBy varchar(20),--Column Name changed and the data type has been changed from date to +varchar +TypeOfContact varchar(20) +)) + +/*Listing 5-5. Retrieving a Contact’s ID, Name, Title, and DOB with an SP */ +ALTER PROCEDURE Person.GetContactDetails +AS +BEGIN +SET NOCOUNT ON +-- Retrieve Name and title for a given PersonID +SELECT p.BusinessEntityID, p.FirstName + ' ' + COALESCE(p.MiddleName,'') + ' ' + +p.LastName, ct.[Name], cast(p.ModifiedDate as varchar(20)), 'Vendor Contact' +FROM [Purchasing].[Vendor] AS v +INNER JOIN [Person].[BusinessEntityContact] bec +ON bec.[BusinessEntityID] = v.[BusinessEntityID] +INNER JOIN [Person].ContactType ct +ON ct.[ContactTypeID] = bec.[ContactTypeID] +INNER JOIN [Person].[Person] p +ON p.[BusinessEntityID] = bec.[PersonID]; +SELECT p.BusinessEntityID, p.FirstName + ' ' + COALESCE(p.MiddleName,'') + ' ' + +p.LastName, ct.[Name], cast(p.ModifiedDate as varchar(20)), p.Suffix, 'Store Contact' +FROM [Sales].[Store] AS s +INNER JOIN [Person].[BusinessEntityContact] bec +ON bec.[BusinessEntityID] = s.[BusinessEntityID] +INNER JOIN [Person].ContactType ct +ON ct.[ContactTypeID] = bec.[ContactTypeID] +INNER JOIN [Person].[Person] p +ON p.[BusinessEntityID] = bec.[PersonID]; +END; +GO + +/*Listing 5-6. Calling the Modified Person.GetContactDetails SP */ +--Call procedure to get consumer information +EXEC Person.GetContactDetails with result sets( +--Return Vendor Contact Details +( +ContactID int,--Column Name changed +ContactName varchar(200),--Column Name changed +Title varchar(50),--Column Name changed +LastUpdatedBy varchar(20),--Column Name changed and the data type has been changed from date to +varchar +TypeOfContact varchar(20) +), +--Return Store Contact Details +( +ContactID int,--Column Name changed +ContactName varchar(200),--Column Name changed +Title varchar(50),--Column Name changed +LastUpdatedBy varchar(20),--Column Name changed and the data type has been changed from date to +varchar +Suffix varchar(5), +TypeOfContact varchar(20) +) +) + +/*Listing 5-7. Dropping the Person.GetEmployee SP */ +DROP PROCEDURE Person.GetEmployee; + +/*Listing 5-8. Procedure to Calculate and Retrieve Running Total for Sales */ +CREATE PROCEDURE Sales.GetSalesRunningTotal (@Year int) +AS +BEGIN +WITH RunningTotalCTE +AS +( +SELECT soh.SalesOrderNumber, +soh.OrderDate, +soh.TotalDue, +( +SELECT SUM(soh1.TotalDue) +FROM Sales.SalesOrderHeader soh1 +WHERE soh1.SalesOrderNumber <= soh.SalesOrderNumber +) AS RunningTotal, +SUM(soh.TotalDue) OVER () AS GrandTotal +FROM Sales.SalesOrderHeader soh +WHERE DATEPART(year, soh.OrderDate) = @Year +GROUP BY soh.SalesOrderNumber, +soh.OrderDate, +soh.TotalDue +) +SELECT rt.SalesOrderNumber, +rt.OrderDate, +rt.TotalDue, +rt.RunningTotal, +(rt.RunningTotal / rt.GrandTotal) * 100 AS PercentTotal +FROM RunningTotalCTE rt +ORDER BY rt.SalesOrderNumber; +RETURN 0; +END; +GO + +EXEC Sales.GetSalesRunningTotal @Year = 2005; +GO + +/*Listing 5 - 9. Recommended Product List SP */ +CREATE PROCEDURE Production.GetProductRecommendations (@ProductID int = 776) +AS +BEGIN +WITH RecommendedProducts +( +ProductID, +ProductSubCategoryID, +TotalQtyOrdered, +TotalDollarsOrdered +) +AS +( +SELECT +od2.ProductID, +p1.ProductSubCategoryID, +SUM(od2.OrderQty) AS TotalQtyOrdered, +SUM(od2.UnitPrice * od2.OrderQty) AS TotalDollarsOrdered +FROM Sales.SalesOrderDetail od1 +INNER JOIN Sales.SalesOrderDetail od2 +ON od1.SalesOrderID = od2.SalesOrderID +INNER JOIN Production.Product p1 +ON od2.ProductID = p1.ProductID +WHERE od1.ProductID = @ProductID +AND od2.ProductID <> @ProductID +GROUP BY +od2.ProductID, +p1.ProductSubcategoryID +) +SELECT TOP(10) ROW_NUMBER() OVER +( +ORDER BY rp.TotalQtyOrdered DESC +) AS Rank, +rp.TotalQtyOrdered, +rp.ProductID, +rp.TotalDollarsOrdered, +p.[Name] +FROM RecommendedProducts rp +INNER JOIN Production.Product p +ON rp.ProductID = p.ProductID +WHERE rp.ProductSubcategoryID <> +( +SELECT ProductSubcategoryID +FROM Production.Product +WHERE ProductID = @ProductID +) +ORDER BY TotalQtyOrdered DESC; +END; +GO + +/*Listing 5 - 10. Getting a Recommended Product List */ +EXECUTE Production..GetProductRecommendations 773; + +/*Listing 5 - 11. The Towers of Hanoi Puzzle */ +-- This stored procedure displays all the discs in the appropriate +-- towers. +CREATE PROCEDURE dbo.ShowTowers +AS +BEGIN +-- Each disc is displayed like this "===3===" where the number is the disc +-- and the width of the === signs on either side indicates the width of the +-- disc. +-- These CTEs are designed for displaying the discs in proper order on each +-- tower. +WITH FiveNumbers(Num) -- Recursive CTE generates table with numbers 1...5 +AS +( +SELECT 1 +UNION ALL +SELECT Num + 1 +FROM FiveNumbers +WHERE Num < 5 +), +GetTowerA (Disc) -- The discs for Tower A +AS +( +SELECT COALESCE(a.Disc, -1) AS Disc +FROM FiveNumbers f +LEFT JOIN #TowerA a +ON f.Num = a.Disc +), +GetTowerB (Disc) -- The discs for Tower B +AS +( +SELECT COALESCE(b.Disc, -1) AS Disc +FROM FiveNumbers f +LEFT JOIN #TowerB b +ON f.Num = b.Disc +), +GetTowerC (Disc) -- The discs for Tower C +AS +( +SELECT COALESCE(c.Disc, -1) AS Disc +FROM FiveNumbers f +LEFT JOIN #TowerC c +ON f.Num = c.Disc +) +-- This SELECT query generates the text representation for all three towers +-- and all five discs. FULL OUTER JOIN is used to represent the towers in a +-- side-by-side format. +SELECT CASE a.Disc +WHEN 5 THEN ' =====5===== ' +WHEN 4 THEN ' ====4==== ' +WHEN 3 THEN '===3=== ' +WHEN 2 THEN ' ==2== ' +WHEN 1 THEN ' =1= ' +ELSE ' | ' +END AS Tower_A, +CASE b.Disc +WHEN 5 THEN ' =====5===== ' +WHEN 4 THEN ' ====4==== ' +WHEN 3 THEN ' ===3=== ' +WHEN 2 THEN ' ==2== ' +WHEN 1 THEN ' =1= ' +ELSE ' | ' +END AS Tower_B, +CASE c.Disc +WHEN 5 THEN ' =====5===== ' +WHEN 4 THEN ' ====4==== ' +WHEN 3 THEN ' ===3=== ' +WHEN 2 THEN ' ==2== ' +WHEN 1 THEN ' =1= ' +ELSE ' | ' +END AS Tower_C +FROM ( +SELECT ROW_NUMBER() OVER(ORDER BY Disc) AS Num, +COALESCE(Disc, -1) AS Disc +FROM GetTowerA +) a +FULL OUTER JOIN ( +SELECT ROW_NUMBER() OVER(ORDER BY Disc) AS Num, +COALESCE(Disc, -1) AS Disc +FROM GetTowerB +) b +ON a.Num = b.Num +FULL OUTER JOIN ( +SELECT ROW_NUMBER() OVER(ORDER BY Disc) AS Num, +COALESCE(Disc, -1) AS Disc +FROM GetTowerC +) c +ON b.Num = c.Num +ORDER BY a.Num; +END; +GO +-- This SP moves a single disc from the specified source tower to the +-- specified destination tower. +CREATE PROCEDURE dbo.MoveOneDisc (@Source nchar(1), +@Dest nchar(1)) +AS +BEGIN +-- @SmallestDisc is the smallest disc on the source tower +DECLARE @SmallestDisc int = 0; +-- IF ... ELSE conditional statement gets the smallest disc from the +-- correct source tower +IF @Source = N'A' +BEGIN +-- This gets the smallest disc from Tower A +SELECT @SmallestDisc = MIN(Disc) +FROM #TowerA; +-- Then delete it from Tower A +DELETE FROM #TowerA +WHERE Disc = @SmallestDisc; +END +ELSE IF @Source = N'B' +BEGIN +-- This gets the smallest disc from Tower B +SELECT @SmallestDisc = MIN(Disc) +FROM #TowerB; +-- Then delete it from Tower B +DELETE FROM #TowerB +WHERE Disc = @SmallestDisc; +END +ELSE IF @Source = N'C' +BEGIN +-- This gets the smallest disc from Tower C +SELECT @SmallestDisc = MIN(Disc) +FROM #TowerC; +-- Then delete it from Tower C +DELETE FROM #TowerC +WHERE Disc = @SmallestDisc; +END +-- Show the disc move performed +SELECT N'Moving Disc (' + CAST(COALESCE(@SmallestDisc, 0) AS nchar(1)) + +N') from Tower ' + @Source + N' to Tower ' + @Dest + ':' AS Description; +-- Perform the move - INSERT the disc from the source tower into the +-- destination tower +IF @Dest = N'A' +INSERT INTO #TowerA (Disc) VALUES (@SmallestDisc); +ELSE IF @Dest = N'B' +INSERT INTO #TowerB (Disc) VALUES (@SmallestDisc); +ELSE IF @Dest = N'C' +INSERT INTO #TowerC (Disc) VALUES (@SmallestDisc); +-- Show the towers +EXECUTE dbo.ShowTowers; +END; +GO +-- This SP moves multiple discs recursively +CREATE PROCEDURE dbo.MoveDiscs (@DiscNum int, +@MoveNum int OUTPUT, +@Source nchar(1) = N'A', +@Dest nchar(1) = N'C', +@Aux nchar(1) = N'B' +) +AS +BEGIN +-- If the number of discs to move is 0, the solution has been found +IF @DiscNum = 0 +PRINT N'Done'; +ELSE +BEGIN +-- If the number of discs to move is 1, go ahead and move it +IF @DiscNum = 1 +BEGIN +-- Increase the move counter by 1 +SELECT @MoveNum += 1; +-- And finally move one disc from source to destination +EXEC dbo.MoveOneDisc @Source, @Dest; +END +ELSE +BEGIN +-- Determine number of discs to move from source to auxiliary tower +DECLARE @n int = @DiscNum - 1; +-- Move (@DiscNum - 1) discs from source to auxiliary tower +EXEC dbo.MoveDiscs @n, @MoveNum OUTPUT, @Source, @Aux, @Dest; +-- Move 1 disc from source to final destination tower +EXEC dbo.MoveDiscs 1, @MoveNum OUTPUT, @Source, @Dest, @Aux; +-- Move (@DiscNum - 1) discs from auxiliary to final destination tower +EXEC dbo.MoveDiscs @n, @MoveNum OUTPUT, @Aux, @Dest, @Source; +END; +END; +END; +GO +-- This SP creates the three towers and populates Tower A with 5 discs +CREATE PROCEDURE dbo.SolveTowers +AS +BEGIN +-- SET NOCOUNT ON to eliminate system messages that will clutter up +-- the Message display +SET NOCOUNT ON; +-- Create the three towers: Tower A, Tower B, and Tower C +CREATE TABLE #TowerA (Disc int PRIMARY KEY NOT NULL); +CREATE TABLE #TowerB (Disc int PRIMARY KEY NOT NULL); +CREATE TABLE #TowerC (Disc int PRIMARY KEY NOT NULL); +-- Populate Tower A with all five discs +INSERT INTO #TowerA (Disc) +VALUES (1), (2), (3), (4), (5); +-- Initialize the move number to 0 +DECLARE @MoveNum int = 0; +-- Show the initial state of the towers +EXECUTE dbo.ShowTowers; +-- Solve the puzzle. Notice you don't need to specify the parameters +-- with defaults +EXECUTE dbo.MoveDiscs 5, @MoveNum OUTPUT; +-- How many moves did it take? +PRINT N'Solved in ' + CAST (@MoveNum AS nvarchar(10)) + N' moves.'; +-- Drop the temp tables to clean up - always a good idea. +DROP TABLE #TowerC; +DROP TABLE #TowerB; +DROP TABLE #TowerA; +-- SET NOCOUNT OFF before we exit +SET NOCOUNT OFF; +END; +GO + +/*Listing 5 - 12. Creating a Table Type */ +CREATE TYPE HumanResources.LastNameTableType +AS TABLE (LastName nvarchar(50) NOT NULL PRIMARY KEY); +GO + +/*Listing 5 - 13. Simple Procedure Accepting a Table-valued Parameter */ +CREATE PROCEDURE HumanResources.GetEmployees +(@LastNameTable HumanResources.LastNameTableType READONLY) +AS +BEGIN +SELECT +p.LastName, +p.FirstName, +p.MiddleName, +e.NationalIDNumber, +e.Gender, +e.HireDate +FROM HumanResources.Employee e +INNER JOIN Person.Person p +ON e.BusinessEntityID = p.BusinessEntityID +INNER JOIN @LastNameTable lnt +ON p.LastName = lnt.LastName +ORDER BY +p.LastName, +p.FirstName, +p.MiddleName; +END; +GO + +/*Listing 5 - 14. Calling a Procedure with a Table-valued Parameter */ +DECLARE @LastNameList HumanResources.LastNameTableType; +INSERT INTO @LastNameList +(LastName) +VALUES +(N'Walters'), +(N'Anderson'), +(N'Chen'), +(N'Rettig'), +(N'Lugo'), +(N'Zwilling'), +(N'Johnson'); +EXECUTE HumanResources.GetEmployees @LastNameList; + +/*Listing 5 - 15. Procedure to Retrieve SP Statistics with DMVs and DMFs */ +CREATE PROCEDURE dbo.GetProcStats (@order varchar(100) = 'use') +AS +BEGIN +WITH GetQueryStats +( +plan_handle, +total_elapsed_time, +total_logical_reads, +total_logical_writes, +total_physical_reads +) +AS +( +SELECT +qs.plan_handle, +SUM(qs.total_elapsed_time) AS total_elapsed_time, +SUM(qs.total_logical_reads) AS total_logical_reads, +SUM(qs.total_logical_writes) AS total_logical_writes, +SUM(qs.total_physical_reads) AS total_physical_reads +FROM sys.dm_exec_query_stats qs +GROUP BY qs.plan_handle +) +SELECT +DB_NAME(st.dbid) AS database_name, +OBJECT_SCHEMA_NAME(st.objectid, st.dbid) AS schema_name, +OBJECT_NAME(st.objectid, st.dbid) AS proc_name, +SUM(cp.usecounts) AS use_counts, +SUM(cp.size_in_bytes) AS size_in_bytes, +SUM(qs.total_elapsed_time) AS total_elapsed_time, +CAST +( +SUM(qs.total_elapsed_time) AS decimal(38, 4) +) / SUM(cp.usecounts) AS avg_elapsed_time_per_use, +SUM(qs.total_logical_reads) AS total_logical_reads, +CAST +( +SUM(qs.total_logical_reads) AS decimal(38, 4) +) / SUM(cp.usecounts) AS avg_logical_reads_per_use, +SUM(qs.total_logical_writes) AS total_logical_writes, +CAST +( +SUM(qs.total_logical_writes) AS decimal(38, 4) +) / SUM(cp.usecounts) AS avg_logical_writes_per_use, +SUM(qs.total_physical_reads) AS total_physical_reads, +CAST +( +SUM(qs.total_physical_reads) AS decimal(38, 4) +) / SUM(cp.usecounts) AS avg_physical_reads_per_use, +st.text +FROM sys.dm_exec_cached_plans cp +CROSS APPLY sys.dm_exec_sql_text(cp.plan_handle) st +INNER JOIN GetQueryStats qs +ON cp.plan_handle = qs.plan_handle +INNER JOIN sys.procedures p +ON st.objectid = p.object_id +WHERE p.type IN ('P', 'PC') +GROUP BY st.dbid, st.objectid, st.text +ORDER BY +CASE @order +WHEN 'name' THEN OBJECT_NAME(st.objectid) +WHEN 'size' THEN SUM(cp.size_in_bytes) +WHEN 'read' THEN SUM(qs.total_logical_reads) +WHEN 'write' THEN SUM(qs.total_logical_writes) +ELSE SUM(cp.usecounts) +END DESC; +END; +GO + +/*Listing 5 - 16. Retrieving SP Statistics */ +EXEC dbo.GetProcStats @order = 'use'; +GO + +/*Listing 5 - 17. Simple Procedure to Demonstrate Parameter Sniffing */ +CREATE PROCEDURE Production.GetProductsByName +@Prefix NVARCHAR(100) +AS +BEGIN +SELECT +p.Name, +p.ProductID +FROM Production.Product p +WHERE p.Name LIKE @Prefix; +END; +GO + +/*Listing 5 - 18. Overriding Parameter Sniffing in an SP */ +ALTER PROCEDURE Production.GetProductsByName +@Prefix NVARCHAR(100) +AS +BEGIN +DECLARE @PrefixVar NVARCHAR(100) = @Prefix; +SELECT +p.Name, +p.ProductID +FROM Production.Product p +WHERE p.Name LIKE @PrefixVar; +END; +GO + +/*Listing 5 - 19. SP to Retrieve Orders by Salesperson */ +CREATE PROCEDURE Sales.GetSalesBySalesPerson (@SalesPersonId int) +AS +BEGIN +SELECT +soh.SalesOrderID, +soh.OrderDate, +soh.TotalDue +FROM Sales.SalesOrderHeader soh +WHERE soh.SalesPersonID = @SalesPersonId; +END; +GO + +/*Listing 5 - 20. Retrieving Sales for Salesperson 277 */ +EXECUTE Sales.GetSalesBySalesPerson 277; + +/*Listing 5 - 21. Executing an SP with Recompilation */ +EXECUTE Sales.GetSalesBySalesPerson 285 WITH RECOMPILE; + +/*Listing 5 - 22. Adding Statement-Level Recompilation to the SP */ +ALTER PROCEDURE Sales.GetSalesBySalesPerson (@SalesPersonId int) +AS +BEGIN +SELECT +soh.SalesOrderID, +soh.OrderDate, +soh.TotalDue +FROM Sales.SalesOrderHeader soh +WHERE soh.SalesPersonID = @SalesPersonId +OPTION (RECOMPILE); +END; +GO + +/*Listing 5 - 23. SP to Retutn List of Stored Procedures That Have Been Recompiled */ +CREATE PROCEDURE dbo.GetRecompiledProcs +AS +BEGIN +SELECT +sql_text.text, +stats.sql_handle, +stats.plan_generation_num, +stats.creation_time, +stats.execution_count, +sql_text.dbid, +sql_text.objectid +FROM sys.dm_exec_query_stats stats +Cross apply sys.dm_exec_sql_text(sql_handle) as sql_text +WHERE stats.plan_generation_num > 1 +and sql_text.objectid is not null --Filter adhoc queries +ORDER BY stats.plan_generation_num desc +END; +GO + +/*Listing 5 - 24. Retrieving SP Statistics */ +EXEC dbo.GetRecompiledProcs; +GO diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch06/ch06.sql b/Pro T-SQL 2012 Programmer's Guide/Ch06/ch06.sql new file mode 100644 index 0000000..13e51fe --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch06/ch06.sql @@ -0,0 +1,476 @@ +-------------------------------------------------- +-- Listing 6-1. Disabling and Enabling Triggers -- +-------------------------------------------------- + +DISABLE TRIGGER HumanResources.EmployeeUpdateTrigger +ON HumanResources.Employee; +GO + +SELECT + name, + OBJECT_SCHEMA_NAME(parent_id) + '.' + OBJECT_NAME(parent_id) as Parent +FROM sys.triggers +WHERE is_disabled = 1; +GO + +ENABLE TRIGGER HumanResources.EmployeeUpdateTrigger +ON HumanResources.Employee; +GO + +-- disabling and enabling all triggers on the object +DISABLE TRIGGER ALL ON HumanResources.Employee; +ENABLE TRIGGER ALL ON HumanResources.Employee; +GO + +------------------------------------------------------------ +-- Listing 6-2. HumanResources.EmployeeUpdateTrigger Code -- +------------------------------------------------------------ +CREATE TRIGGER HumanResources.EmployeeUpdateTrigger +ON HumanResources.Employee +AFTER UPDATE +NOT FOR REPLICATION +AS +BEGIN + -- stop if no row was affected + IF @@ROWCOUNT = 0 RETURN + -- Turn off "rows affected" messages + SET NOCOUNT ON; + + -- Make sure at least one row was affected + -- Update ModifiedDate for all affected rows + UPDATE HumanResources.Employee + SET ModifiedDate = GETDATE() + WHERE EXISTS + ( + SELECT 1 + FROM inserted i + WHERE i.BusinessEntityID = HumanResources.Employee.BusinessEntityID + ); +END; +GO + +--------------------------------------------------------------- +-- Listing 6-3. Testing HumanResources.EmployeeUpdateTrigger -- +--------------------------------------------------------------- +UPDATE HumanResources.Employee +SET MaritalStatus = 'M' +WHERE BusinessEntityID IN (1, 2); + +SELECT BusinessEntityID, NationalIDNumber, MaritalStatus, ModifiedDate +FROM HumanResources.Employee +WHERE BusinessEntityID IN (1, 2); +GO + +------------------------------------------ +-- Listing 6-4. DML Audit Logging Table -- +------------------------------------------ +CREATE TABLE dbo.DmlActionLog ( + EntryNum int IDENTITY(1, 1) PRIMARY KEY NOT NULL, + SchemaName sysname NOT NULL, + TableName sysname NOT NULL, + ActionType nvarchar(10) NOT NULL, + ActionXml xml NOT NULL, + LoginName sysname NOT NULL, + ApplicationName sysname NOT NULL, + HostName sysname NOT NULL, + ActionDateTime datetime2(0) NOT NULL DEFAULT (SYSDATETIME()) +); +GO + +-------------------------------------------- +-- Listing 6-5. DML Audit Logging Trigger -- +-------------------------------------------- +CREATE TRIGGER HumanResources.DepartmentChangeAudit +ON HumanResources.Department +AFTER INSERT, UPDATE, DELETE +NOT FOR REPLICATION +AS +BEGIN + -- stop if no row was affected + IF @@ROWCOUNT = 0 RETURN + + -- Turn off "rows affected" messages + SET NOCOUNT ON; + + DECLARE @ActionType nvarchar(10), @ActionXml xml; + + -- Get count of inserted rows + DECLARE @inserted_count int = ( + SELECT COUNT(*) + FROM inserted + ); + -- Get count of deleted rows + DECLARE @deleted_count int = ( + SELECT COUNT(*) + FROM deleted + ); + + -- Determine the type of DML action that fired the trigger + SET @ActionType = CASE + WHEN (@inserted_count > 0) AND (@deleted_count = 0) THEN N'insert' + WHEN (@inserted_count = 0) AND (@deleted_count > 0) THEN N'delete' + ELSE N'update' + END; + + -- Use FOR XML AUTO to retrieve before and after snapshots of the changed + -- data in XML format + SELECT @ActionXml = COALESCE + ( + ( + SELECT * + FROM deleted + FOR XML AUTO + ), N'' + ) + COALESCE + ( + ( + SELECT * + FROM inserted + FOR XML AUTO + ), N'' + ); + + -- Insert a row for the logged action in the audit logging table + INSERT INTO dbo.DmlActionLog + ( + SchemaName, + TableName, + ActionType, + ActionXml, + LoginName, + ApplicationName, + HostName + ) + SELECT + OBJECT_SCHEMA_NAME(@@PROCID, DB_ID()), + OBJECT_NAME(t.parent_id, DB_ID()), + @ActionType, + @ActionXml, + SUSER_SNAME(), + APP_NAME(), + HOST_NAME() + FROM sys.triggers t + WHERE t.object_id = @@PROCID; +END; +GO + +-------------------------------------------------------- +-- Listing 6-6. Testing the DML Audit Logging Trigger -- +-------------------------------------------------------- +UPDATE HumanResources.Department SET Name = N'Information Technology' +WHERE DepartmentId = 11; + +INSERT INTO HumanResources.Department +( + Name, + GroupName +) +VALUES +( + N'Customer Service', + N'Sales and Marketing' +); + +DELETE +FROM HumanResources.Department +WHERE Name = N'Customer Service'; + +SELECT + EntryNum, + SchemaName, + TableName, + ActionType, + ActionXml, + LoginName, + ApplicationName, + HostName, + ActionDateTime +FROM dbo.DmlActionLog; +GO + +---------------------------------------------- +-- Listing 6-7. Turning Off Nested Triggers -- +---------------------------------------------- +EXEC sp_configure 'nested triggers', 0; +RECONFIGURE; +GO + +------------------------------------------------------- +-- Listing 6-8. Turning Off Recursive AFTER Triggers -- +------------------------------------------------------- +ALTER DATABASE AdventureWorks SET RECURSIVE_TRIGGERS OFF; +GO + +---------------------------------------------------- +-- Listing 6-9. Trigger to Enforce Standard Sizes -- +---------------------------------------------------- +CREATE TRIGGER Production.ProductEnforceStandardSizes +ON Production.Product +AFTER INSERT, UPDATE +NOT FOR REPLICATION +AS +BEGIN + -- Make sure at least one row was affected and either the Size or + -- SizeUnitMeasureCode column was changed + IF (@@ROWCOUNT > 0) AND (UPDATE(SizeUnitMeasureCode) OR UPDATE(Size)) + BEGIN + -- Eliminate "rows affected" messages + SET NOCOUNT ON; + -- Only accept recognized units of measure or NULL + IF EXISTS + ( + SELECT 1 + FROM inserted + WHERE NOT + ( SizeUnitMeasureCode IN (N'M', N'DM', N'CM', N'MM', N'IN') + OR SizeUnitMeasureCode IS NULL + ) + ) + BEGIN + -- If the unit of measure wasn't recognized raise an error and roll back + -- the transaction + RAISERROR ('Invalid Size Unit Measure Code.', 10, 127); + ROLLBACK TRANSACTION; + END + ELSE + BEGIN + -- If the unit of measure is a recognized unit of measure then set the + -- SizeUnitMeasureCode to centimeters and perform the Size conversion + UPDATE Production.Product + SET SizeUnitMeasureCode = CASE + WHEN Production.Product.SizeUnitMeasureCode IS NULL THEN NULL ELSE N'CM' END, + Size = CAST ( + CAST ( CAST(i.Size AS float) * + CASE i.SizeUnitMeasureCode + WHEN N'M' THEN 100.0 + WHEN N'DM' THEN 10.0 + WHEN N'CM' THEN 1.0 + WHEN N'MM' THEN 0.10 + WHEN N'IN' THEN 2.54 + END + AS int + ) AS nvarchar(5) + ) + FROM inserted i + WHERE Production.Product.ProductID = i.ProductID + AND i.SizeUnitMeasureCode IS NOT NULL; + END; + END; +END; +GO + +--------------------------------------------------------------- +-- Listing 6-10. Testing the Trigger by Adding a New Product -- +--------------------------------------------------------------- +UPDATE Production.Product +SET Size = N'600', + SizeUnitMeasureCode = N'MM' +WHERE ProductId = 680; + +UPDATE Production.Product +SET Size = N'22.85', + SizeUnitMeasureCode = N'IN' +WHERE ProductId = 706; + +SELECT ProductID, + Name, + ProductNumber, + Size, + SizeUnitMeasureCode +FROM Production.Product +WHERE ProductID IN (680, 706); +GO + +------------------------------------------------ +-- Listing 6-11. INSTEAD OF Trigger on a View -- +------------------------------------------------ +CREATE TRIGGER Sales.vIndividualCustomerUpdate +ON Sales.vIndividualCustomer +INSTEAD OF UPDATE +NOT FOR REPLICATION +AS +BEGIN + -- First make sure at least one row was affected + IF @@ROWCOUNT = 0 RETURN + -- Turn off "rows affected" messages + SET NOCOUNT ON; + -- Initialize a flag to indicate update success + DECLARE @UpdateSuccessful bit = 0; + + -- Check for updatable columns in the first table + IF UPDATE(FirstName) OR UPDATE(MiddleName) OR UPDATE(LastName) + BEGIN + -- Update columns in the base table + UPDATE Person.Person + SET FirstName = i.FirstName, + MiddleName = i.MiddleName, + LastName = i.LastName + FROM inserted i + WHERE i.BusinessEntityID = Person.Person.BusinessEntityID; + + -- Set flag to indicate success + SET @UpdateSuccessful = 1; + END; + -- If updatable columns from the second table were specified, update those + -- columns in the base table + IF UPDATE(EmailAddress) + BEGIN + -- Update columns in the base table + UPDATE Person.EmailAddress + SET EmailAddress = i.EmailAddress + FROM inserted i + WHERE i.BusinessEntityID = Person.EmailAddress.BusinessEntityID; + + -- Set flag to indicate success + SET @UpdateSuccessful = 1; + END; + -- If the update was not successful, raise an error and roll back the + -- transaction + IF @UpdateSuccessful = 0 + RAISERROR('Must specify updatable columns.', 10, 127); +END; +GO + +----------------------------------------------------------------- +-- Listing 6-12. Updating a View Through an INSTEAD OF Trigger -- +----------------------------------------------------------------- +UPDATE Sales.vIndividualCustomer +SET FirstName = N'Dave', + MiddleName = N'Robert', + EmailAddress = N'dave.robinett@adventure-works.com' +WHERE BusinessEntityID = 1699; + +SELECT BusinessEntityID, FirstName, MiddleName, LastName, EmailAddress +FROM Sales.vIndividualCustomer +WHERE BusinessEntityID = 1699; +GO + +---------------------------------------------------- +-- Listing 6-14. CREATE TABLE DDL Trigger Example -- +---------------------------------------------------- +-- Create a table to log DDL CREATE TABLE actions +CREATE TABLE dbo.DdlActionLog +( + EntryId int NOT NULL IDENTITY(1, 1) PRIMARY KEY, + EventType nvarchar(200) NOT NULL, + PostTime datetime NOT NULL, + LoginName sysname NOT NULL, + UserName sysname NOT NULL, + ServerName sysname NOT NULL, + SchemaName sysname NOT NULL, + DatabaseName sysname NOT NULL, + ObjectName sysname NOT NULL, + ObjectType sysname NOT NULL, + CommandText nvarchar(max) NOT NULL +); +GO + +CREATE TRIGGER AuditCreateTable +ON DATABASE +FOR CREATE_TABLE +AS +BEGIN + -- Assign the XML event data to an xml variable + DECLARE @eventdata xml = EVENTDATA(); + + -- Shred the XML event data and insert a row in the log table + INSERT INTO dbo.DdlActionLog + ( + EventType, + PostTime, + LoginName, + UserName, + ServerName, + SchemaName, + DatabaseName, + ObjectName, + ObjectType, + CommandText + ) + SELECT + EventNode.value(N'EventType[1]', N'nvarchar(200)'), + EventNode.value(N'PostTime[1]', N'datetime'), + EventNode.value(N'LoginName[1]', N'sysname'), + EventNode.value(N'UserName[1]', N'sysname'), + EventNode.value(N'ServerName[1]', N'sysname'), + EventNode.value(N'SchemaName[1]', N'sysname'), + EventNode.value(N'DatabaseName[1]', N'sysname'), + EventNode.value(N'ObjectName[1]', N'sysname'), + EventNode.value(N'ObjectType[1]', N'sysname'), + EventNode.value(N'(TSQLCommand/CommandText)[1]', 'nvarchar(max)') + FROM @eventdata.nodes('/EVENT_INSTANCE') EventTable(EventNode); +END; +GO + +------------------------------------------------------------------------- +-- Listing 6-15. Testing the DDL Trigger with a CREATE TABLE Statement -- +------------------------------------------------------------------------- +CREATE TABLE dbo.MyTable (i int); +GO + +SELECT + EntryId, + EventType, + UserName, + ObjectName, + CommandText +FROM DdlActionLog; +GO + +------------------------------------------ +-- Listing 6-16. Dropping a DDL Trigger -- +------------------------------------------ +DROP TRIGGER AuditCreateTable +ON DATABASE; +GO + +------------------------------------------------------------------- +-- Listing 6-17. Creating a Test Login and Logon Denial Schedule -- +------------------------------------------------------------------- +CREATE LOGIN PublicUser WITH PASSWORD = 'p@$$w0rd'; +GO + +USE Master; + +CREATE TABLE dbo.DenyLogonSchedule ( + UserId sysname NOT NULL, + DayOfWeek tinyint NOT NULL, + TimeStart time NOT NULL, + TimeEnd time NOT NULL, + PRIMARY KEY (UserId, DayOfWeek, TimeStart, TimeEnd) + ); + GO + +INSERT INTO dbo.DenyLogonSchedule ( + UserId, + DayOfWeek, + TimeStart, + TimeEnd +) VALUES ( + 'PublicUser', + 7, + '21:00:00', + '23:00:00' + ); +GO + +---------------------------------------- +-- Listing 6-18. Sample Logon Trigger -- +---------------------------------------- +USE Master; + +CREATE TRIGGER DenyLogons +ON ALL SERVER +WITH EXECUTE AS 'sa' +FOR LOGON +AS +BEGIN + IF EXISTS ( SELECT 1 + FROM Master .dbo.DenyLogonSchedule + WHERE UserId = ORIGINAL_LOGIN() + AND DayOfWeek = DATEPART(WeekDay, GETDATE()) + AND CAST(GETDATE() AS TIME) BETWEEN TimeStart AND TimeEnd + ) BEGIN + ROLLBACK TRANSACTION; + END; +END; diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch08/9781430245964_Natarajan_Ch08_CommonTableExpressionsAndWindowingFunctions.sql b/Pro T-SQL 2012 Programmer's Guide/Ch08/9781430245964_Natarajan_Ch08_CommonTableExpressionsAndWindowingFunctions.sql new file mode 100644 index 0000000..ac4eb9d --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch08/9781430245964_Natarajan_Ch08_CommonTableExpressionsAndWindowingFunctions.sql @@ -0,0 +1,417 @@ +/*Listing 8-1. Simple CTE */ +WITH GetNamesCTE ( +BusinessEntityID, +FirstName, +MiddleName, +LastName ) +AS ( +SELECT +BusinessEntityID, FirstName, MiddleName, LastName +FROM Person.Person ) SELECT +BusinessEntityID, +FirstName, +MiddleName, +LastName FROM GetNamesCTE +; + +/*Listing 8-2. Multiple CTEs */ +WITH GetNamesCTE ( +BusinessEntityID, +FirstName, +MiddleName, +LastName ) +AS ( +SELECT +BusinessEntityID, FirstName, MiddleName, LastName +FROM Person.Person ), +GetContactCTE ( +BusinessEntityID, +FirstName, +MiddleName, LastName, Email, HomePhoneNumber +) +AS ( SELECT gn.BusinessEntityID, gn.FirstName, gn.MiddleName, gn.LastName, ea.EmailAddress, +pp.PhoneNumber FROM GetNamesCTE gn LEFT JOIN Person.EmailAddress ea +ON gn.BusinessEntityID = ea.BusinessEntityID LEFT JOIN Person.PersonPhone pp ON +gn.BusinessEntityID = pp.BusinessEntityID AND pp.PhoneNumberTypeID = 2 ) +SELECT BusinessEntityID, FirstName, MiddleName, LastName, Email, +HomePhoneNumber FROM GetContactCTE; + +/*Listing 8-3. Simple Recursive CTE */ +WITH Numbers (n) AS ( SELECT 1 AS n +UNION ALL +SELECT n + 1 FROM Numbers WHERE n < 10 ) +SELECT n FROM Numbers; + +/*Listing 8-4. Recursive CTE with MAXRECURSION Option */ +WITH Numbers (n) AS ( SELECT 0 AS n +UNION ALL +SELECT n + 1 +FROM Numbers +WHERE n < 1000 ) +SELECT n FROM Numbers OPTION (MAXRECURSION 1000); + +/*Listing 8-5. Recursive BOM CTE */ +DECLARE @ComponentID int = 774; +WITH BillOfMaterialsCTE +( +BillOfMaterialsID, +ProductAssemblyID, +ComponentID, +Quantity, +Level +) +AS +( +SELECT +bom.BillOfMaterialsID, +bom.ProductAssemblyID, +bom.ComponentID, +bom.PerAssemblyQty AS Quantity, +0 AS Level +FROM Production.BillOfMaterials bom +WHERE bom.ComponentID = @ComponentID +UNION ALL +SELECT +bom.BillOfMaterialsID, +bom.ProductAssemblyID, +bom.ComponentID, +bom.PerAssemblyQty, +Level + 1 +FROM Production.BillOfMaterials bom +ComponentID 774 +ComponentID 516 +ComponentID 497 +ProductAssemblyID 774 +ProductAssemblyID 516 +INNER JOIN BillOfMaterialsCTE bomcte +ON bom.ProductAssemblyID = bomcte.ComponentID +WHERE bom.EndDate IS NULL +) +SELECT +bomcte.ProductAssemblyID, +p.ProductID, +p.ProductNumber, +p.Name, +p.Color, +bomcte.Quantity, +bomcte.Level +FROM BillOfMaterialsCTE bomcte +INNER JOIN Production.Product p +ON bomcte.ComponentID = p.ProductID +order by bomcte.Level; + +/*Listing 8-6. ROW_NUMBER with Partitioning */ +SELECT +ROW_NUMBER() OVER +( +PARTITION BY +LastName +ORDER BY +LastName, +FirstName, +MiddleName +) AS Number, +LastName, +FirstName, +MiddleName +FROM Person.Person; + +/*Listing 8-7. OFFSET/FETCH Example */ +CREATE PROCEDURE Person.GetContacts +@StartPageNum int, +@RowsPerPage int +AS +SELECT +LastName, +FirstName, +MiddleName +FROM Person.Person +ORDER BY +LastName, +FirstName, +MiddleName +OFFSET (@StartPageNum - 1) * @RowsPerPage ROWS +FETCH NEXT @RowsPerPage ROWS ONLY; +GO + +/*Listing 8-8. Ranking AdventureWorks Daily Sales Totals */ +WITH TotalSalesBySalesDate +( +DailySales, +OrderDate +) +AS +( +SELECT +SUM(soh.SubTotal) AS DailySales, +soh.OrderDate +FROM Sales.SalesOrderHeader soh +WHERE soh.OrderDate > = '20060101' +AND soh.OrderDate < '20070101' +GROUP BY soh.OrderDate +) +SELECT +RANK() OVER +( +ORDER BY +DailySales DESC +) AS Ranking, +DailySales, +OrderDate +FROM TotalSalesBySalesDate +ORDER BY Ranking; + +/*Listing 8-9. Determining the daily sales rankings partitioned by month */ +WITH TotalSalesBySalesDatePartitioned +( +DailySales, +OrderMonth, +OrderDate +) +AS +( +SELECT +SUM(soh.SubTotal) AS DailySales, +DATENAME(MONTH, soh.OrderDate) AS OrderMonth, +soh.OrderDate +FROM Sales.SalesOrderHeader soh +WHERE soh.OrderDate > = '20050101' +AND soh.OrderDate < '20060101' +GROUP BY soh.OrderDate +) +SELECT +RANK() OVER +( +PARTITION BY +OrderMonth +ORDER BY +DailySales DESC +) AS Ranking, +DailySales, +OrderMonth, +OrderDate +FROM TotalSalesBySalesDatePartitioned +ORDER BY DATEPART(mm,OrderDate), +Ranking; + +/*Listing 8-10. Using DENSE_RANK to Rank Best Daily Sales Per Month */ +WITH TotalSalesBySalesDatePartitioned +( +DailySales, +OrderMonth, +OrderDate +) +AS +( +SELECT +SUM(soh.SubTotal) AS DailySales, +DATENAME(MONTH, soh.OrderDate) AS OrderMonth, +soh.OrderDate +FROM Sales.SalesOrderHeader soh +WHERE soh.OrderDate > = '20050101' +AND soh.OrderDate < '20060101' +GROUP BY soh.OrderDate +) +SELECT +RANK() OVER +( +PARTITION BY +OrderMonth +ORDER BY +DailySales DESC +) AS Ranking, +DENSE_RANK() OVER +( +PARTITION BY +OrderMonth +ORDER BY +DailySales DESC +) AS Dense_Ranking, +DailySales, +OrderMonth, +OrderDate +FROM TotalSalesBySalesDatePartitioned +ORDER BY DATEPART(mm,OrderDate), +Ranking; + +/*Listing 8-11. Using NTILE to Group and Rank Salespeople */ +WITH SalesTotalBySalesPerson +( +SalesPersonID, SalesTotal +) +AS +( +SELECT +soh.SalesPersonID, SUM(soh.SubTotal) AS SalesTotal +FROM Sales.SalesOrderHeader soh +WHERE DATEPART(YEAR, soh.OrderDate) = 2005 +AND DATEPART(MONTH, soh.OrderDate) = 7 +GROUP BY soh.SalesPersonID ) SELECT +NTILE(4) OVER +( ORDER BY +st.SalesTotal DESC +) AS Tile, +p.LastName, +p.FirstName, +p.MiddleName, +st.SalesPersonID, +st.SalesTotal FROM SalesTotalBySalesPerson st INNER JOIN Person.Person p +ON st.SalesPersonID = p.BusinessEntityID ; + +/*Listing 8-13. Using the OVER Clause with SUM */ +SELECT +PurchaseOrderID, +ProductID, +OrderQty, +UnitPrice, +LineTotal, +SUM(LineTotal) +OVER (PARTITION BY PurchaseOrderID +ORDER BY ProductId +RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) +AS CumulativeOrderOty +FROM Purchasing.PurchaseOrderDetail; + +/*Listing 8-14. Query results due to default framing specification */ +SELECT +PurchaseOrderID, +ProductID, +OrderQty, +UnitPrice, +LineTotal, +SUM(LineTotal) +OVER (PARTITION BY PurchaseOrderID +ORDER BY ProductId +) +AS TotalSalesDefaultFraming, +SUM(LineTotal) +OVER (PARTITION BY PurchaseOrderID +ORDER BY ProductId RANGE BETWEEN UNBOUNDED PRECEDING +AND UNBOUNDED FOLLOWING +) +AS TotalSalesDefinedFraming +FROM Purchasing.PurchaseOrderDetail +ORDER BY PurchaseOrderID; + +/*Listing 8-15. Using the OVER Clause define frame sizes to return two-day, moving average */ +SELECT +PurchaseOrderID, +ProductID, +Duedate, +LineTotal, +Avg(LineTotal) +OVER (ORDER BY Duedate +ROWS BETWEEN 1 PRECEDING AND CURRENT ROW) +AS [2DayAvg] +FROM Purchasing.PurchaseOrderDetail +ORDER BY Duedate; + +/*Listing 8-16. Defining frames from within the OVER clause to calcualte running total */ +SELECT +PurchaseOrderID, +ProductID, +OrderQty, +UnitPrice, +LineTotal, +SUM(LineTotal) OVER (PARTITION BY ProductId ORDER BY DueDate +RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS CumulativeTotal, +ROW_NUMBER() OVER (PARTITION BY ProductId ORDER BY DueDate ) AS No +FROM Purchasing.PurchaseOrderDetail +ORDER BY ProductId, DueDate; + +/*Listing 8-17. Using the CUME_DIST function */ +SELECT +round(SUM(TotalDue),1) AS Sales, +LastName, +FirstName, +SalesPersonId, +CUME_DIST() OVER (ORDER BY round(SUM(TotalDue),1)) as CUME_DIST +FROM +Sales.SalesOrderHeader soh +JOIN Sales.vSalesPerson sp +ON soh.SalesPersonID = sp.BusinessEntityID +GROUP BY SalesPersonID,LastName,FirstName; + +/*Listing 8-18. Using the PERCENT_RANK function */ +SELECT +round(SUM(TotalDue),1) AS Sales, +LastName, +FirstName, +SalesPersonId, +CUME_DIST() OVER (ORDER BY round(SUM(TotalDue),1)) as CUME_DIST +,PERCENT_RANK() OVER (ORDER BY round(SUM(TotalDue),1)) as PERCENT_RANK +FROM +Sales.SalesOrderHeader soh +JOIN Sales.vSalesPerson sp +ON soh.SalesPersonID = sp.BusinessEntityID +GROUP BY SalesPersonID,LastName,FirstName; + +/*Listing 8-19. Using PERCENTILE_CONT AND PERCENTILE_DISC */ +SELECT +round(SUM(TotalDue),1) AS Sales, +LastName, +FirstName, +SalesPersonId, +AccountNumber, +PERCENTILE_CONT(0.4) WITHIN GROUP (ORDER BY round(SUM(TotalDue),1)) +OVER(PARTITION BY AccountNumber ) AS PERCENTILE_CONT, +PERCENTILE_DISC(0.4) WITHIN GROUP(ORDER BY round(SUM(TotalDue),1)) +OVER(PARTITION BY AccountNumber ) AS PERCENTILE_DISC +FROM +Sales.SalesOrderHeader soh +JOIN Sales.vSalesPerson sp +ON soh.SalesPersonID = sp.BusinessEntityID +GROUP BY AccountNumber,SalesPersonID,LastName,FirstName + +/*Listing 8-20. Using the LAG function */ +WITH ProductCostHistory AS +(SELECT +ProductID, +LAG(StandardCost) OVER (PARTITION BY ProductID ORDER BY ProductID) AS PreviousProductCost, +StandardCost AS CurrentProductCost, +Startdate,Enddate +FROM Production.ProductCostHistory +) +SELECT +ProductID, +PreviousProductCost, +CurrentProductCost, +StartDate, +EndDate +FROM ProductCostHistory +WHERE Enddate IS NULL + +/* Listing 8-21. Using the LEAD function */ +Select +LastName, +SalesPersonID, +Sum(SubTotal) CurrentMonthSales, +DateNAME(Month,OrderDate) Month, +DateName(Year,OrderDate) Year, +LEAD(Sum(SubTotal),1) OVER (ORDER BY SalesPersonID, OrderDate) TotalSalesNextMonth +FROM +Sales.SalesOrderHeader soh +JOIN Sales.vSalesPerson sp +ON soh.SalesPersonID = sp.BusinessEntityID +WHERE DateName(Year,OrderDate) = 2007 +GROUP BY +FirstName, LastName, SalesPersonID,OrderDate +ORDER BY SalesPersonID,OrderDate; + +/*Listing 8-22. Using FIRST_VALUE and LAST_VALUE */ +SELECT DISTINCT +LastName, +SalesPersonID, +datename(year,OrderDate) OrderYear, +datename(month, OrderDate) OrderMonth, +FIRST_VALUE(SubTotal) OVER (PARTITION BY SalesPersonID, OrderDate ORDER BY +SalesPersonID ) FirstSalesAmount, +LAST_VALUE(SubTotal) OVER (PARTITION BY SalesPersonID, OrderDate ORDER BY +SalesPersonID) LastSalesAmount, +OrderDate +FROM +Sales.SalesOrderHeader soh +JOIN Sales.vSalesPerson sp +ON soh.SalesPersonID = sp.BusinessEntityID +ORDER BY OrderDate; + diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch10/ch10.sql b/Pro T-SQL 2012 Programmer's Guide/Ch10/ch10.sql new file mode 100644 index 0000000..8aa04a1 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch10/ch10.sql @@ -0,0 +1,772 @@ +------------------------------------ +-- Listing 10-1. Unicode Handling -- +------------------------------------ +DECLARE + @string VARCHAR(50) = 'hello earth', + @nstring NVARCHAR(50) = 'hello earth'; + +SELECT + DATALENGTH(@string) as DatalengthString, + DATALENGTH(@nstring) as DatalengthNString, + LEN(@string) as lenString, + LEN(@nstring) as lenNString; +GO + +----------------------------------------------------------------- +-- Listing 10-2. Comparison of .WRITE Clause and String Append -- +----------------------------------------------------------------- +-- Turn off messages that can affect performance +SET NOCOUNT ON; +-- Create and initially populate a test table +CREATE TABLE #test ( + Id int NOT NULL PRIMARY KEY, + String varchar(max) NOT NULL +); + +INSERT INTO #test ( + Id, + String +) VALUES ( + 1, + '' +), ( + 2, + '' +); +-- Initialize variables and get start time +DECLARE @i int = 1; +DECLARE @quote varchar(50) = 'Four score and seven years ago...'; +DECLARE @start_time datetime2(7) = SYSDATETIME(); +-- Loop 2500 times and use .WRITE to append to a varchar(max) column +WHILE @i < 2500 +BEGIN + UPDATE #test + SET string.WRITE(@quote, LEN(string), LEN(@quote)) + WHERE Id = 1; + + SET @i += 1; +END; + +SELECT '.WRITE Clause', DATEDIFF(ms, @start_time, SYSDATETIME()), 'ms'; + +-- Reset variables and get new start time +SET @i = 1; +SET @start_time = SYSDATETIME(); + +-- Loop 2500 times and use string append to a varchar(max) column +WHILE @i < 2500 +BEGIN + UPDATE #test + SET string += @quote + WHERE Id = 2; + + SET @i += 1; +END; + +SELECT 'Append Method', DATEDIFF(ms, @start_time, SYSDATETIME()), 'ms'; + +SELECT + Id, + String, + LEN(String) +FROM #test; + +DROP TABLE #test; +GO + +----------------------------------------------------------------------------- +-- Listing 10-3. Use the Full Range of 32-bit Integer for IDENTITY Columns -- +----------------------------------------------------------------------------- +CREATE TABLE dbo.bigtable ( + bigtableId int identity(-2147483648,1) NOT NULL +); + +INSERT INTO dbo.bigtable DEFAULT VALUES; +INSERT INTO dbo.bigtable DEFAULT VALUES; + +SELECT * FROM dbo.bigtable; + +----------------------------------- +-- Listing 10-4. Date Comparison -- +----------------------------------- +SELECT * +FROM Person.StateProvince +WHERE ModifiedDate = '2008-03-11'; +GO + +------------------------------------------------------ +-- Listing 10-5. Date Comparison Executed Correctly -- +------------------------------------------------------ +SELECT * +FROM Person.StateProvince +WHERE ModifiedDate BETWEEN '2008-03-11' AND '2008-03-12'; +-- or +SELECT * +FROM Person.StateProvince +WHERE CONVERT(CHAR(10), ModifiedDate, 126) = '2008-03-11'; +GO + +-------------------------------------------------- +-- Listing 10-6. Correcting the Date Comparison -- +-------------------------------------------------- +SELECT * +FROM Production.Product +WHERE ModifiedDate BETWEEN '2008-03-11' AND '2008-03-11 23:59:59.997'; +-- or +SELECT * +FROM Person.StateProvince +WHERE ModifiedDate >= '2008-03-11' AND ModifiedDate < '2008-03-12'; + +----------------------------------------------- +-- Listing 10-7. Sample Date Data Type Usage -- +----------------------------------------------- +-- August 19, 14 C.E. +DECLARE @d1 date = '0014-08-19'; + +-- February 26, 1983 +DECLARE @d2 date = '1983-02-26'; +SELECT @d1 AS Date1, @d2 AS Date2, DATEDIFF(YEAR, @d1, @d2) AS YearsDifference; +GO + +------------------------------------------------------ +-- Listing 10-8. Demonstrating Time Data Type Usage -- +------------------------------------------------------ +-- 6:25:19.1 AM +DECLARE @start_time time(1) = '06:25:19.1'; -- 1 digit fractional precision +-- 6:25:19.1234567 PM +DECLARE @end_time time = '18:25:19.1234567'; -- default fractional precision +SELECT @start_time AS start_time, @end_time AS end_time, +DATEADD(HOUR, 6, @start_time) AS StartTimePlus, DATEDIFF(HOUR, @start_time, @end_time) AS + EndStartDiff; +GO + +-------------------------------------------------------------- +-- Listing 10-9. Declaring and Querying Datetime2 Variables -- +-------------------------------------------------------------- +DECLARE @start_dt2 datetime2 = '1972-07-06T07:13:28.8230234', + @end_dt2 datetime2 = '2009-12-14T03:14:13.2349832'; +SELECT @start_dt2 AS start_dt2, @end_dt2 AS end_dt2; +GO + +---------------------------------------------------- +-- Listing 10-10. Datetimeoffset Data Type Sample -- +---------------------------------------------------- +DECLARE @start_dto datetimeoffset = '1492-10-12T13:29:59.9999999-05:00'; +SELECT @start_dto AS start_to, DATEPART(YEAR, @start_dto) AS start_year; +GO + +------------------------------------------------------- +-- Listing 10-11. Demonstration of Datetime Rounding -- +------------------------------------------------------- +SELECT CAST('2011-12-31T23:59:59.999' as datetime) as WhatTimeIsIt; +GO + +-------------------------------------------------------- +-- Listing 10-12. CONVERT() and FORMAT() Usage Sample -- +-------------------------------------------------------- +DECLARE @dt2 datetime2 = '2011-12-31T23:59:59'; + +SELECT FORMAT(@dt2, 'F', 'en-US') as with_format, + CONVERT(varchar(50), @dt2, 109) as with_convert; +GO + +--------------------------------------------------------------------- +-- Listing 10-13. How to Check the Current Language of the Session -- +--------------------------------------------------------------------- +SELECT language +FROM sys.dm_exec_sessions +WHERE session_id = @@SPID; +-- or +SELECT @@LANGUAGE; +GO + +------------------------------------------------------------------- +-- Listing 10-14. Language Dependent Date String Representations -- +------------------------------------------------------------------- +DECLARE @lang sysname; + +SET @lang = @@LANGUAGE + +SELECT CAST('12/31/2012' as datetime2); --this works + +SET LANGUAGE 'spanish'; + +SELECT + CASE WHEN TRY_CAST('12/31/2012' as datetime2) IS NULL + THEN 'Cast failed' + ELSE 'Cast succeeded' +END AS Result; + +SET LANGUAGE @lang; +GO + +-------------------------------------------- +-- Listing 10-15. Usage of SET DATEFORMAT -- +-------------------------------------------- +SET DATEFORMAT mdy; +SET LANGUAGE 'spanish'; +SELECT CAST('12/31/2012' as datetime2); --this works now +GO + +------------------------------------------------------ +-- Listing 10-17. Using the Date and Time Functions -- +------------------------------------------------------ +SELECT SYSDATETIME() AS [SYSDATETIME]; +SELECT SYSUTCDATETIME() AS [SYSUTCDATETIME]; +SELECT SYSDATETIMEOFFSET() AS [SYSDATETIMEOFFSET]; +GO + +--------------------------------------------------------- +-- Listing 10-18. Adding an Offset to a Datetime Value -- +--------------------------------------------------------- +DECLARE @current datetime = CURRENT_TIMESTAMP; +SELECT @current AS [No_0ffset]; +SELECT TODATETIMEOFFSET(@current, '-04:00') AS [With_0ffset]; +GO + +------------------------------------------------------------------------ +-- Listing 10-19. Converting a Datetimeoffset to Several Time Offsets -- +------------------------------------------------------------------------ +DECLARE @current datetimeoffset = '2012-05-04 19:30:00 -07:00'; +SELECT 'Los Angeles' AS [Location], @current AS [Current Time] +UNION ALL +SELECT 'New York', SWITCHOFFSET(@current, '-04:00') +UNION ALL +SELECT 'Bermuda', SWITCHOFFSET(@current, '-03:00') +UNION ALL +SELECT 'London', SWITCHOFFSET(@current, '+01:00'); +GO + +------------------------------------------- +-- Listing 10-20. Using Uniqueidentifier -- +------------------------------------------- +CREATE TABLE dbo.Document ( + DocumentId uniqueidentifier NOT NULL PRIMARY KEY DEFAULT (NEWID()) +); + +INSERT INTO dbo.Document DEFAULT VALUES; +INSERT INTO dbo.Document DEFAULT VALUES; +INSERT INTO dbo.Document DEFAULT VALUES; + +SELECT * FROM dbo.Document; + +------------------------------------------------ +-- Listing 10-21. Generating Sequential GUIDs -- +------------------------------------------------ +CREATE TABLE #TestSeqID ( + ID uniqueidentifier DEFAULT NEWSEQUENTIALID() PRIMARY KEY NOT NULL, + Num int NOT NULL +); + +INSERT INTO #TestSeqID (Num) +VALUES (1), (2), (3); + +SELECT ID, Num +FROM #TestSeqID; + +DROP TABLE #TestSeqID; +GO + +--------------------------------------------------------------------- +-- Listing 10-22. Creating the Hierarchyid Bill of Materials Table -- +--------------------------------------------------------------------- +CREATE TABLE Production.HierBillOfMaterials +( + BomNode hierarchyid NOT NULL PRIMARY KEY NONCLUSTERED, + ProductAssemblyID int NULL, + ComponentID int NULL, + UnitMeasureCode nchar(3) NULL, + PerAssemblyQty decimal(8, 2) NULL, + BomLevel AS BomNode.GetLevel() +); +GO + +----------------------------------------------------------------------- +-- Listing 10-23. Converting AdventureWorks BOMs to hierarchyid Form -- +----------------------------------------------------------------------- +;WITH BomChildren +( + ProductAssemblyID, + ComponentID +) +AS +( + SELECT + b1.ProductAssemblyID, + b1.ComponentID + FROM Production.BillOfMaterials b1 + GROUP BY + b1.ProductAssemblyID, + b1.ComponentID +), +BomPaths +( + Path, + ComponentID, + ProductAssemblyID +) +AS +( + SELECT + hierarchyid::GetRoot() AS Path, + NULL, + NULL + UNION ALL + + SELECT + CAST + ('/' + CAST (bc.ComponentId AS varchar(30)) + '/' AS hierarchyid) AS Path, + bc.ComponentID, + bc.ProductAssemblyID + FROM BomChildren AS bc + WHERE bc.ProductAssemblyID IS NULL + + UNION ALL + + SELECT + CAST + (bp.path.ToString() + + CAST(bc.ComponentID AS varchar(30)) + '/' AS hierarchyid) AS Path, + bc.ComponentID, + bc.ProductAssemblyID + FROM BomChildren AS bc + INNER JOIN BomPaths AS bp + ON bc.ProductAssemblyID = bp.ComponentID +) +INSERT INTO Production.HierBillOfMaterials +( + BomNode, + ProductAssemblyID, + ComponentID, + UnitMeasureCode, + PerAssemblyQty +) +SELECT + bp.Path, + bp.ProductAssemblyID, + bp.ComponentID, + bom.UnitMeasureCode, + bom.PerAssemblyQty +FROM BomPaths AS bp +LEFT OUTER JOIN Production.BillOfMaterials bom + ON bp.ComponentID = bom.ComponentID + AND COALESCE(bp.ProductAssemblyID, -1) = COALESCE(bom.ProductAssemblyID, -1) +WHERE bom.EndDate IS NULL +GROUP BY + bp.path, + bp.ProductAssemblyID, + bp.ComponentID, + bom.UnitMeasureCode, + bom.PerAssemblyQty; +GO + +------------------------------------------------- +-- Listing 10-24. Viewing the Hierarchyid BOMs -- +------------------------------------------------- +SELECT + BomNode, + BomNode.ToString(), + ProductAssemblyID, + ComponentID, + UnitMeasureCode, + PerAssemblyQty, + BomLevel +FROM Production.HierBillOfMaterialsORDER BY BomNode; +GO + +---------------------------------------------------------------- +-- Listing 10-25. Retrieving Descendant Nodes of Assembly 749 -- +---------------------------------------------------------------- +DECLARE @CurrentNode hierarchyid; + +SELECT @CurrentNode = BomNode +FROM Production.HierBillOfMaterials +WHERE ProductAssemblyID = 749; + +SELECT + BomNode, + BomNode.ToString(), + ProductAssemblyID, + ComponentID, + UnitMeasureCode, + PerAssemblyQty, + BomLevel +FROM Production.HierBillOfMaterials +WHERE @CurrentNode.IsDescendantOf(BomNode) = 1; +GO + +-------------------------------------------------------------- +-- Listing 10-26. Representing Wyoming as a Geometry Object -- +-------------------------------------------------------------- +DECLARE @Wyoming geometry; +SET @Wyoming = geometry::STGeomFromText ('POLYGON ( +( -104.053108 41.698246, -104.054993 41.564247, +-104.053505 41.388107, -104.051201 41.003227, +-104.933968 40.994305, -105.278259 40.996365, +-106.202896 41.000111, -106.328545 41.001316, +-106.864838 40.998489, -107.303436 41.000168, +-107.918037 41.00341, -109.047638 40.998474, +-110.001457 40.997646, -110.062477 40.99794, +-111.050285 40.996635, -111.050911 41.25848, +-111.050323 41.578648, -111.047951 41.996265, +-111.046028 42.503323, -111.048447 43.019962, +-111.04673 43.284813, -111.045998 43.515606, +-111.049629 43.982632, -111.050789 44.473396, +-111.050842 44.664562, -111.05265 44.995766, +-110.428894 44.992348, -110.392006 44.998688, +-109.994789 45.002853, -109.798653 44.99958, +-108.624573 44.997643, -108.258568 45.00016, +-107.893715 44.999813, -106.258644 44.996174, +-106.020576 44.997227, -105.084465 44.999832, +-105.04126 45.001091, -104.059349 44.997349, +-104.058975 44.574368, -104.060547 44.181843, +-104.059242 44.145844, -104.05899 43.852928, +-104.057426 43.503738, -104.05867 43.47916, +-104.05571 43.003094, -104.055725 42.614704, +-104.053009 41.999851, -104.053108 41.698246) )', 0); + +SELECT @Wyoming as Wyoming; +GO + +------------------------------------------------------------------------- +-- Listing 10-27. Using GML to Represent Wyoming as a Geography Object -- +------------------------------------------------------------------------- +DECLARE @Wyoming geography; +SET @Wyoming = geography::GeomFromGml (' + + + + 41.698246 -104.053108 41.999851 -104.053009 + 43.003094 -104.05571 43.503738 -104.057426 + 44.145844 -104.059242 44.574368 -104.058975 + 45.001091 -105.04126 44.997227 -106.020576 + 44.999813 -107.893715 44.997643 -108.624573 + 45.002853 -109.994789 44.992348 -110.428894 + 44.664562 -111.050842 43.982632 -111.049629 + 43.284813 -111.04673 42.503323 -111.046028 + 41.578648 -111.050323 40.996635 -111.050285 + 40.997646 -110.001457 41.00341 -107.918037 + 40.998489 -106.864838 41.000111 -106.202896 + 40.994305 -104.933968 41.388107 -104.053505 + 41.698246 -104.053108 + + + +', 4269); +GO + +---------------------------------------------------------------------- +-- Listing 10-28. Are the Statue of Liberty and Laramie in Wyoming? -- +---------------------------------------------------------------------- +DECLARE @Wyoming geography, + @StatueOfLiberty geography, + @Laramie geography; + +SET @Wyoming = geography::GeomFromGml (' + + + + 41.698246 -104.053108 41.999851 -104.053009 + 43.003094 -104.05571 43.503738 -104.057426 + 44.145844 -104.059242 44.574368 -104.058975 + 45.001091 -105.04126 44.997227 -106.020576 + 44.999813 -107.893715 44.997643 -108.624573 + 45.002853 -109.994789 44.992348 -110.428894 + 44.664562 -111.050842 43.982632 -111.049629 + 43.284813 -111.04673 42.503323 -111.046028 + 41.578648 -111.050323 40.996635 -111.050285 + 40.997646 -110.001457 41.00341 -107.918037 + 40.998489 -106.864838 41.000111 -106.202896 + 40.994305 -104.933968 41.388107 -104.053505 + 41.698246 -104.053108 + + + +', 4269); + +SET @StatueOfLiberty = geography::GeomFromGml(' + + 40.689124 -74.044483 + + ', 4269); + +SET @Laramie = geography::GeomFromGml(' + + 41.312928 -105.587253 + + ', 4269); + +SELECT 'Is the Statue of Liberty in Wyoming?', + CASE @Wyoming.STIntersects(@StatueOfLiberty) + WHEN 0 THEN 'No' + ELSE 'Yes' + END AS Answer +UNION +SELECT 'Is Laramie in Wyoming?', + CASE @Wyoming.STIntersects(@Laramie) + WHEN 0 THEN 'No' + ELSE 'Yes' + END; +GO + +--------------------------------------------- +-- Listing 10-29. Creating a Spatial Index -- +--------------------------------------------- +CREATE SPATIAL INDEX SIX_Location ON MyTable (SpatialColumn); +GO + +-------------------------------------------------------------- +-- Listing 10-30. Enabling FILESTREAM Support on the Server -- +-------------------------------------------------------------- +EXEC sp_configure 'filestream access level', 2; +RECONFIGURE; +GO + +----------------------------------------------------------------- +-- Listing 10-31. Viewing FILESTREAM Configuration Information -- +----------------------------------------------------------------- +SELECT + SERVERPROPERTY('ServerName') AS ServerName, + SERVERPROPERTY('FilestreamSharename') AS ShareName, + CASE SERVERPROPERTY('FilestreamEffectiveLevel') + WHEN 0 THEN 'Disabled' + WHEN 1 THEN 'T-SQL Access Only' + WHEN 2 THEN 'Local T-SOL/File System Access Only' + WHEN 3 THEN 'Local T-SOL/File System and Remote File System Access' + END AS Effective_Level, + CASE SERVERPROPERTY('FilestreamConfiguredLevel') + WHEN 0 THEN 'Disabled' + WHEN 1 THEN 'T-SQL Access Only' + WHEN 2 THEN 'Local T-SOL/File System Access Only' + WHEN 3 THEN 'Local T-SOL/File System and Remote File System Access' + END AS Configured_Level; +GO + +---------------------------------------------------------------- +-- Listing 10-32. CREATE DATABASE for AdventureWorks Database -- +---------------------------------------------------------------- +CREATE DATABASE [AdventureWorks] + CONTAINMENT = NONE + ON PRIMARY +( NAME = N'AdventureWorks2012_Data', FILENAME = N'C:\sqldata\MSSQL11.MSSQLSERVER\MSSQL\DATA\AdventureWorks2012_Data.mdf' , SIZE = 226304KB , MAXSIZE = UNLIMITED, FILEGROWTH = 16384KB ), + FILEGROUP [FILESTREAM1] CONTAINS FILESTREAM DEFAULT +( NAME = N'AdventureWordsFS', FILENAME = N'C:\sqldata\MSSQL11.MSSQLSERVER\MSSQL\DATA\AdventureWordsFS' , MAXSIZE = UNLIMITED) + LOG ON +( NAME = N'AdventureWorks2012_Log', FILENAME = N'C:\sqldata\MSSQL11.MSSQLSERVER\MSSQL\DATA\AdventureWorks2012_log.ldf' , SIZE = 5696KB , MAXSIZE = UNLIMITED, FILEGROWTH = 10%); +GO + +-------------------------------------------------------------------------- +-- Listing 10-33. Adding a FILESTREAM Filegroup to an Existing Database -- +-------------------------------------------------------------------------- +ALTER DATABASE AdventureWorks +ADD FILEGROUP FILESTREAM1 CONTAINS FILESTREAM; +GO +ALTER DATABASE AdventureWorks +ADD FILE +( +NAME = N' AdventureWordsFS', +FILENAME = N' C:\sqldata\MSSQL11.MSSQLSERVER\MSSQL\DATA\AdventureWordsFS' ) +TO FILEGROUP FILESTREAM1; +GO + +----------------------------------------------------------------- +-- Listing 10-34. Production.Document FILESTREAM-Enabled Table -- +----------------------------------------------------------------- +CREATE TABLE Production.DocumentFS ( + DocumentNode hierarchyid NOT NULL PRIMARY KEY, + DocumentLevel AS (DocumentNode.GetLevel()), + Title nvarchar(50) NOT NULL, + Owner int NOT NULL, + FolderFlag bit NOT NULL, + FileName nvarchar(400) NOT NULL, + FileExtension nvarchar(8) NOT NULL, + Revision nchar(5) NOT NULL, + ChangeNumber int NOT NULL, + Status tinyint NOT NULL, + DocumentSummary nvarchar(max) NULL, + Document varbinary(max) FILESTREAM NULL, + rowguid uniqueidentifier ROWGUIDCOL NOT NULL UNIQUE, + ModifiedDate datetime NOT NULL +); +GO + +INSERT INTO Production.DocumentFS + (DocumentNode, Title, Owner, FolderFlag, FileName, FileExtension, Revision, ChangeNumber, Status, DocumentSummary, Document, rowguid, ModifiedDate) +SELECT + DocumentNode, Title, Owner, FolderFlag, FileName, FileExtension, Revision, ChangeNumber, Status, DocumentSummary, Document, rowguid, ModifiedDate +FROM Production.Document; +GO + +-------------------------------------------------------- +-- Listing 10-35. Querying a FILESTREAM-Enabled Table -- +-------------------------------------------------------- +SELECT + d.Title, + d.Document.PathName() AS LOB_Path, + d.Document AS LOB_Data +FROM Production.DocumentFS d +WHERE d.Document IS NOT NULL; +GO + +-------------------------------------------------------------------- +-- Listing 10-36. Creating a Database with a FILESTREAM Filegroup -- +-------------------------------------------------------------------- +CREATE DATABASE cliparts +CONTAINMENT = NONE +ON PRIMARY +( NAME = N'cliparts', FILENAME = N'C:\sqldata\MSSQL11.MSSQLSERVER\MSSQL\DATA\cliparts.mdf' , SIZE = 5120KB , FILEGROWTH = 1024KB ), +FILEGROUP [filestreamFG1] CONTAINS FILESTREAM +( NAME = N'filestream1', FILENAME = N'C:\sqldata\MSSQL11.MSSQLSERVER\MSSQL\DATA\filestream1' ) +LOG ON +( NAME = N'cliparts_log', FILENAME = N'C:\sqldata\MSSQL11.MSSQLSERVER\MSSQL\DATA\cliparts_log.ldf' , SIZE = 1024KB , FILEGROWTH = 10%); +GO + +ALTER DATABASE [cliparts] SET FILESTREAM( NON_TRANSACTED_ACCESS = FULL, DIRECTORY_NAME = N'cliparts' ); +GO + +------------------------------------------- +-- Listing 10-37. Creating the Filetable -- +------------------------------------------- +USE [cliparts]; +GO + +CREATE TABLE dbo.OpenClipartsLibrary AS FILETABLE +WITH + ( + FILETABLE_DIRECTORY = 'OpenClipartsLibrary' + ); +GO + +INSERT INTO dbo.OpenClipartsLibrary (name,is_directory) +VALUES ('import_20120501',1); +GO + +----------------------------------------------------------- +-- Listing 10-38. Inserting a Directory in the Filetable -- +----------------------------------------------------------- +INSERT INTO dbo.OpenClipartsLibrary (name, is_directory) +VALUES ('directory01',1); +GO + +--------------------------------------------- +-- Listing 10-39. Inserting a Subdirectory -- +--------------------------------------------- +INSERT INTO dbo.OpenClipartsLibrary + (name, is_directory, creation_time, path_locator) +SELECT + 'directory02',1, dateadd(year, -1, sysdatetime()), path_locator.GetDescendant(NULL, NULL) +FROM dbo.OpenClipartsLibrary +WHERE name = 'directory01' +AND is_directory = 1 +AND parent_path_locator IS NULL; +GO + +---------------------------------------------- +-- Listing 10-40. Using FileTableRootPath() -- +---------------------------------------------- +USE cliparts; + +SELECT FileTableRootPath(); +SELECT FileTableRootPath('dbo.OpenClipartsLibrary'); +GO + +-------------------------------------------------- +-- Listing 10-41. Using GetFileNamespacePath(). -- +-------------------------------------------------- +SELECT file_stream.GetFileNamespacePath(1) as path +FROM dbo.OpenClipartsLibrary +WHERE is_directory = 1 +ORDER BY path_locator.GetLevel(), path; +GO + +------------------------------------------------ +-- Listing 10-42. Using Hierarchyid Functions -- +------------------------------------------------ +SELECT l1.name, l1.path_locator.GetLevel(), l2.name as parent_directory +FROM dbo.OpenClipartsLibrary l1 +JOIN dbo.OpenClipartsLibrary l2 ON l1.path_locator.GetAncestor(1) = l2.path_locator +WHERE l1.is_directory = 1; +GO + +----------------------------------------------------- +-- Listing 10-43. Using Parent_path_locator Column -- +----------------------------------------------------- +SELECT l1.name, l1.path_locator.GetLevel(), l2.name as parent_directory +FROM dbo.OpenClipartsLibrary l1 +JOIN dbo.OpenClipartsLibrary l2 ON l1.parent_path_locator = l2.path_locator +WHERE l1.is_directory = 1; +GO + +-------------------------------------------------------------------------- +-- Listing 10-44. Using a CTE to Travel Down the Directories’ Hierarchy -- +-------------------------------------------------------------------------- +;WITH mycte AS ( + SELECT name, path_locator.GetLevel() as Level, path_locator + FROM dbo.OpenClipartsLibrary + WHERE name = 'Yason' + AND is_directory = 1 + + UNION ALL + + SELECT l1.name, l1.path_locator.GetLevel() as Level, l1.path_locator + FROM dbo.OpenClipartsLibrary l1 + JOIN mycte l2 ON l1.parent_path_locator = l2.path_locator + WHERE l1.is_directory = 1 +) +SELECT name, Level +FROM mycte +ORDER BY level, name; +GO + +----------------------------------------------------------------------------------------- +-- Listing 10-45. Using hierarchyid Functions to Travel Down the Directory’s Hierarchy -- +----------------------------------------------------------------------------------------- +SELECT l1.name, l1.path_locator.GetLevel() as Level +FROM dbo.OpenClipartsLibrary l1 +JOIN dbo.OpenClipartsLibrary l2 ON l1.path_locator.IsDescendantOf(l2.path_locator) = 1 OR l1.path_locator = l2.path_locator +WHERE l1.is_directory = 1 +AND l2.is_directory = 1 +AND l2.name = 'Yason' +ORDER BY level, name; +GO + +--------------------------------------------------------- +-- Listing 10-46. Using the GetPathLocator() function. -- +--------------------------------------------------------- +DECLARE @path_locator hierarchyid + +SET @path_locator = GetPathLocator('\\Sql2012\mssqlserver\cliparts\OpenClipartsLibrary\import_20120501\Yason'); + +SELECT * +FROM dbo.OpenClipartsLibrary +WHERE path_locator = @path_locator; +GO + +------------------------------------------------------------------------------------------- +-- Listing 10-47. Creating an Audit Table and a Trigger on the OpenClipartsLibrary Table -- +------------------------------------------------------------------------------------------- +CREATE TABLE dbo.cliparts_log ( + path nvarchar(4000) not null, + deletion_date datetime2(0), + deletion_user sysname, + is_directory bit +) +GO + +CREATE TRIGGER OpenClipartsLibrary_logTrigger +ON [dbo].[OpenClipartsLibrary] +AFTER DELETE +AS BEGIN + IF @@ROWCOUNT = 0 RETURN; + SET NOCOUNT ON; + + INSERT INTO dbo.cliparts_log (path, deletion_date, deletion_user, is_directory) + SELECT name, SYSDATETIME(), SUSER_SNAME(),is_directory + FROM deleted +END; +GO + diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch12/9781430245964_Natarajan_Ch12_XQueryandXPath.sql b/Pro T-SQL 2012 Programmer's Guide/Ch12/9781430245964_Natarajan_Ch12_XQueryandXPath.sql new file mode 100644 index 0000000..a10e9a5 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch12/9781430245964_Natarajan_Ch12_XQueryandXPath.sql @@ -0,0 +1,502 @@ +/*Listing 12 - 1. Retrieving Names and E-mail Addresses with FOR XML PATH */ +SELECT +p.BusinessEntityID AS "Person/ID", +p.FirstName AS "Person/Name/First", +p.MiddleName AS "Person/Name/Middle", +p.LastName AS "Person/Name/Last", +e.EmailAddress AS "Person/Email" +FROM Person.Person p INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID +FOR XML PATH, ROOT('PersonEmailAddress'); + +/*Listing 12 - 2. FOR XML PATH Creating XML Attributes */ +SELECT p.BusinessEntityID AS "Person/@ID", +e.EmailAddress AS "Person/@Email", +p.FirstName AS "Person/Name/First", +p.MiddleName AS "Person/Name/Middle", +p.LastName AS "Person/Name/Last" +FROM Person.Person p INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID FOR XML PATH; + +/*Listing 12 - 3. Using Columns without Names and Wildcards with FOR XML PATH */ +SELECT p.BusinessEntityID AS "*", ',' + e.EmailAddress, +p.FirstName AS "Person/Name/First", +p.MiddleName AS "Person/Name/Middle", +p.LastName AS "Person/Name/Last" FROM Person.Person p INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID FOR XML PATH; + +/*Listing 12 - 4. Two Elements with a Common Parent Element Separated */ +SELECT p.BusinessEntityID AS "@ID", +e.EmailAddress AS "@EmailAddress", +p.FirstName AS "Person/Name/First", +pp.PhoneNumber AS "Phone/BusinessPhone", +p.MiddleName AS "Person/Name/Middle", +p.LastName AS "Person/Name/Last" +FROM Person.Person p +INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID +INNER JOIN Person.PersonPhone pp +ON p.BusinessEntityID = pp.BusinessEntityID +AND pp.PhoneNumberTypeID = 3 FOR XML PATH; + +/*Listing 12 - 5. The FOR XML PATH XPath data Node Test */ +SELECT DISTINCT soh.SalesPersonID AS "SalesPerson/@ID", ( +SELECT soh2.SalesOrderID AS "data()" +FROM Sales.SalesOrderHeader soh2 +WHERE soh2.SalesPersonID = soh.SalesPersonID FOR XML PATH ('') ) AS +"SalesPerson/@Orders", +p.FirstName AS "SalesPerson/Name/First", +p.MiddleName AS "SalesPerson/Name/Middle", +p.LastName AS "SalesPerson/Name/Last", +e.EmailAddress AS "SalesPerson/Email" +FROM Sales.SalesOrderHeader soh +INNER JOIN Person.Person p +ON p.BusinessEntityID = soh.SalesPersonID +INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID +WHERE soh.SalesPersonID IS NOT NULL FOR XML PATH; + +/*Listing 12 - 6. FOR XML with the ELEMENTS XSINIL Option */ +SELECT +p.BusinessEntityID AS "Person/ID", +p.FirstName AS "Person/Name/First", +p.MiddleName AS "Person/Name/Middle", +p.LastName AS "Person/Name/Last", +e.EmailAddress AS "Person/Email" FROM Person.Person p INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID FOR XML PATH, +ELEMENTS XSINIL; + +/*Listing 12 - 7. Using WITH XMLNAMESPACES to Specify Namespaces */ +WITH XMLNAMESPACES(' http://www.apress.com/xml/sampleSqlXmlNameSpace ' as ns) +SELECT +p.BusinessEntityID AS "ns:Person/ID", +p.FirstName AS "ns:Person/Name/First", +p.MiddleName AS "ns:Person/Name/Middle", +p.LastName AS "ns:Person/Name/Last", +e.EmailAddress AS "ns:Person/Email" +FROM Person.Person p +INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID +FOR XML PATH; + +/*Listing 12 - 8. FOR XML PATH Using XPath Node Tests */ +SELECT +p.NameStyle AS "processing-instruction(nameStyle)", +p.BusinessEntityID AS "Person/@ID", +p.ModifiedDate AS "comment()", +pp.PhoneNumber AS "text()", +FirstName AS "Person/Name/First", +MiddleName AS "Person/Name/Middle", +LastName AS "Person/Name/Last", +EmailAddress AS "Person/Email" +FROM Person.Person p +INNER JOIN Person.EmailAddress e +ON p.BusinessEntityID = e.BusinessEntityID +INNER JOIN Person.PersonPhone pp +ON p.BusinessEntityID = pp.BusinessEntityID +FOR XML PATH; + +/*Listing 12 - 9. Retrieving Job Candidates with the query Method */ +SELECT Resume.query +( +N'//*:Name.First, +//*:Name.Middle, +//*:Name.Last, +//*:Edu.Level' +) +FROM HumanResources.JobCandidate; + +/*Listing 12 - 10. Querying with an Absolute Location Path */ +DECLARE @x xml = N'< ?xml version = "1.0"?> + + + + 37.859609 + −122.291673 + + + APress, Inc. + + + + + 37.423268 + −122.086345 + + + Google, Inc. + + + '; +SELECT @x.query(N'/Geocode/Info/Coordinates'); + +/*Listing 12 - 11. Sample Processing-instruction Node Test */ +SELECT CatalogDescription.query(N'/processing-instruction()') AS Processing_Instr +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 12. Sample comment Node Test */ +SELECT CatalogDescription.query(N'//comment()') AS Comments +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 13. Sample node Node Test */ +SELECT CatalogDescription.query(N'//*:Specifications/node()') AS Specifications +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 14. Querying CatalogDescription with No Namespaces */ +SELECT CatalogDescription.query(N'//Specifications/node()') AS Specifications +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 15. Prolog Namespace Declaration */ +SELECT CatalogDescription.query +( +N'declare namespace +p1 = " http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +//p1:Specifications/node()' +) +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 16. Prolog Default Namespace Declaration */ +SELECT CatalogDescription.query +( +N'declare default element namespace +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +//Specifications/node()' +) +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 17. Query with and Without Default Axes */ +SELECT CatalogDescription.query(N'//*:Specifications/node()') AS Specifications +FROM Production.ProductModel +WHERE ProductModelID = 19; +SELECT CatalogDescription.query(N'//child::*:Specifications/child::node()') +AS Specifications +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 18. Sample Using the parent:: Axis */ +DECLARE @x xml = N'< ?xml version = "1.0"?> + + + + 37.859609 + −122.291673 + + + APress, Inc. + + + + + 37.423268 + −122.086345 + + + Google, Inc. + + + '; +SELECT @x.query(N'//Location/parent::node()/Coordinates'); + +/*Listing 12 - 19. XQuery Dynamic XML Construction */ +DECLARE @x xml = N'< ?xml version = "1.0"?> + + + + APress, Inc. + + + + + Google, Inc. + + + '; +SELECT @x.query(N'< Companies> +{ +//Info/Location/Name +} + '); + +/*Listing 12 - 20. Element and Attribute Dynamic Constructors */ +SELECT CatalogDescription.query +( +N'declare namespace +p1 = " http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +//p1:Specifications/node()' +) +FROM Production.ProductModel +WHERE ProductModelID = 19; +DECLARE @x xml = N'< ?xml version = "1.0"?> + + + + APress, Inc. +
+ 2560 Ninth St, Ste 219 + Berkeley + CA + 94710-2500 + US +
+
+
+
'; +SELECT @x.query +( +N'element Companies +{ +element FirstCompany +{ +attribute CompanyID +{ +(//Info/@ID)[1] +}, +(//Info/Location/Name)[1] +} +}' +); + +/*Listing 12 - 21. Value Comparison Examples */ +DECLARE @x xml = N'< ?xml version = "1.0" ?> + +Cat + '; +SELECT @x.query(N'9 eq 9.0 (: 9 is equal to 9.0 :)'); +SELECT @x.query(N'4 gt 3 (: 4 is greater than 3 :)'); +SELECT @x.query(N'(/Animal/text())[1] lt "Dog" (: Cat is less than Dog :)') ; + +/*Listing 12 - 22. Incompatible Type Value Comparison */ +DECLARE @x xml = N''; +SELECT @x.query(N'3.141592 eq "Pi"') ; +Msg 2234, Level 16, State 1, Line 2 +XQuery [query()]: The operator "eq" cannot be applied to "xs:decimal" and "xs:string" operands. + +/*Listing 12 - 23. General Comparison Examples */ +DECLARE @x xml = ''; +SELECT @x.query('(3.141592, 1) = (2, 3.141592) (: true :) '); +SELECT @x.query('(1.0, 2.0, 3.0) = 1 (: true :) '); +SELECT @x.query('("Joe", "Harold") < "Adam" (: false :) '); +SELECT @x.query('xs:date("1999-01-01") < xs:date("2006-01-01") (: true :)'); + +/*Listing 12 - 24. General Comparison with Heterogeneous Sequence */ +DECLARE @x xml = ''; +SELECT @x.query('(xs:date("2006-10-09"), 6.02E23) > xs:date("2007-01-01")'); + +/*Listing 12 - 25. Mixing Nodes and Atomic Values in Sequences */ +DECLARE @x xml = ''; +SELECT @x.query('(1, Testing)'); + +/*Listing 12 - 26. Node Comparison Samples */ +DECLARE @x xml = N'< ?xml version = "1.0"?> + + Test Node + Test Node + Test Node + '; +SELECT @x.query('((/Root/NodeA)[1] is (//NodeA)[1]) (: true :)'); +SELECT @x.query('((/Root/NodeA)[1] is (/Root/NodeA)[2]) (: false :)'); +SELECT @x.query('((/Root/NodeA)[2] is (/Root/NodeB)[1]) (: true :)'); + +/*Listing 12 - 27. Node Comparison That Evaluates to an Empty Sequence */ +DECLARE @x xml = N'< ?xml version = "1.0"?> + + Test Node + '; +SELECT @x.query('((/Root/NodeA)[1] is (/Root/NodeZ)[1]) (: empty sequence :)'); + +/*Listing 12 - 28. The sql:column Function */ +DECLARE @x xml = N''; +SELECT @x.query(N'< Name> + +{ +sql:column("p.BusinessEntityID") +} + + +{ +sql:column("p.FirstName"), +sql:column("p.MiddleName"), +sql:column("p.LastName") +} + + ') +FROM Person.Person p +WHERE p.BusinessEntityID < = 5 +ORDER BY p.BusinessEntityID; + +/*Listing 12 - 29. XQuery sql:column and sql:variable Functions Example */ +/* 10 % discount */ +DECLARE @discount NUMERIC(3, 2); +SELECT @discount = 0.10; +DECLARE @x xml; +SELECT @x = ''; +SELECT @x.query('< Product> + { sql:column("ProductModelID") } + { sql:column("Name") } + { sql:column("ListPrice") } + +{ sql:column("ListPrice") - +(sql:column("ListPrice") * sql:variable("@discount") ) } + + +') +FROM Production.Product p +WHERE ProductModelID = 30; + +/*Listing 12 - 30. Basic XQuery for . . . return Expression */ +SELECT CatalogDescription.query(N'declare namespace ns = +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +for $spec in //ns:ProductDescription/ns:Specifications/* +return fn:string($spec)') AS Description FROM Production.ProductModel WHERE ProductModelID = 19; + +/*Listing 12 - 31. XQuery for . . . return Expression with XML Result */ +SELECT CatalogDescription.query ( +N'declare namespace ns = +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +for $spec in //ns:ProductDescription/ns:Specifications/* return < detail > { +$spec/text() } ' ) AS Description +FROM Production.ProductModel WHERE ProductModelID = 19; + +/*Listing 12 - 32. XQuery Cartesian Product with for Expression */ +SELECT CatalogDescription.query(N'declare namespace ns = +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +for $spec in //ns:ProductDescription/ns:Specifications/*, +$feat in //ns:ProductDescription/*:Features/*:Warranty/node() +return < detail> +{ +$spec/text() +} + +{ +fn:string($feat/.) +} + ' +) AS Description +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 33. Using a Bound Variable in the for Clause */ +SELECT CatalogDescription.query +( +N'declare namespace ns = +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +for $spec in //ns:ProductDescription/ns:Specifications, +$color in $spec/Color +return < color> +{ +$color/text() +} + ' +) AS Color +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 34. where Clause Demonstration */ +SELECT CatalogDescription.query +( +N'declare namespace ns = +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +for $spec in //ns:ProductDescription/ns:Specifications/* +where $spec[ contains( . , "A" ) ] +return < detail> +{ +$spec/text() +} + ' +) AS Detail +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 35. order by Clause */ +SELECT CatalogDescription.query(N'declare namespace ns = +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +for $spec in //ns:ProductDescription/ns:Specifications/* +order by $spec/. descending +return < detail > { $spec/text() } ') AS Detail +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 36. let Clause */ +SELECT CatalogDescription.query +( +N'declare namespace ns = +" http://schemas.microsoft.com/sqlserver/2004/07/adventure-works/ProductModelDescription "; +for $spec in //ns:ProductDescription/ns:Specifications/* +let $val := $spec/text() +order by fn:string($val[1]) ascending +return < spec> +{ +$val +} + ' +) AS Detail +FROM Production.ProductModel +WHERE ProductModelID = 19; + +/*Listing 12 - 37. Create Record to Demonstrate UTF-16 */ +declare @BusinessEntityId int +INSERT INTO Person.BusinessEntity(rowguid, ModifiedDate) +VALUES (NEWID(),CURRENT_TIMESTAMP) +SET @BusinessEntityId = SCOPE_IDENTITY() +INSERT INTO [Person].[Person] +([BusinessEntityID] +,[PersonType] +,[NameStyle] +,[Title] +,[FirstName] +,[MiddleName] +,[LastName] +,[Suffix] +,[EmailPromotion] +,[AdditionalContactInfo] +,[Demographics] +,[rowguid] +,[ModifiedDate]) +VALUES +396 +(@BusinessEntityId, +'EM', +0, +NULL, +N'T' + nchar(0xD834) + nchar(0xDD25), +'J', +'Kim', +NULL, +0, +NULL, +'< IndividualSurvey xmlns = " http://schemas.microsoft.com/sqlserver/2004/07/ +adventure-works/IndividualSurvey">0', +NEWID(), +CURRENT_TIMESTAMP) + + +/*Listing 12 - 38. SQL Server to Check for Presence of Surrogates */ +SELECT +p.NameStyle AS "processing-instruction(nameStyle)", +p.BusinessEntityID AS "Person/@ID", +p.ModifiedDate AS "comment()", +FirstName AS "Person/Name/First", +Len(FirstName) AS "Person/FirstName/Length", +MiddleName AS "Person/Name/Middle", +LastName AS "Person/Name/Last" +FROM Person.Person p +WHERE BusinessEntityID = 20778 +FOR XML PATH; + +/*Listing 12-39. Surroage Pair with UTF-16 and _SC collation */ +SELECT +p.NameStyle AS "processing-instruction(nameStyle)", +p.BusinessEntityID AS "Person/@ID", +p.ModifiedDate AS "comment()", +FirstName AS "Person/Name/First", +Len(FirstName COLLATE Latin1_General_100_CS_AS_SC) AS "Person/FirstName/Length", +MiddleName AS "Person/Name/Middle", +LastName AS "Person/Name/Last" +FROM Person.Person p +WHERE BusinessEntityID = 20778 +FOR XML PATH; diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples.sln b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples.sln new file mode 100644 index 0000000..8094f5f --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples.sln @@ -0,0 +1,22 @@ + +Microsoft Visual Studio Solution File, Format Version 11.00 +# Visual Studio 2010 +Project("{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC}") = "ApressExamples", "ApressExamples\ApressExamples.csproj", "{13E56BB3-CB08-4B05-BE52-0ACA0EA080E1}" +EndProject +Global + GlobalSection(SolutionConfigurationPlatforms) = preSolution + Debug|Any CPU = Debug|Any CPU + Release|Any CPU = Release|Any CPU + EndGlobalSection + GlobalSection(ProjectConfigurationPlatforms) = postSolution + {13E56BB3-CB08-4B05-BE52-0ACA0EA080E1}.Debug|Any CPU.ActiveCfg = Debug|Any CPU + {13E56BB3-CB08-4B05-BE52-0ACA0EA080E1}.Debug|Any CPU.Build.0 = Debug|Any CPU + {13E56BB3-CB08-4B05-BE52-0ACA0EA080E1}.Debug|Any CPU.Deploy.0 = Debug|Any CPU + {13E56BB3-CB08-4B05-BE52-0ACA0EA080E1}.Release|Any CPU.ActiveCfg = Release|Any CPU + {13E56BB3-CB08-4B05-BE52-0ACA0EA080E1}.Release|Any CPU.Build.0 = Release|Any CPU + {13E56BB3-CB08-4B05-BE52-0ACA0EA080E1}.Release|Any CPU.Deploy.0 = Release|Any CPU + EndGlobalSection + GlobalSection(SolutionProperties) = preSolution + HideSolutionNode = FALSE + EndGlobalSection +EndGlobal diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples.suo b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples.suo new file mode 100644 index 0000000..e4572c4 Binary files /dev/null and b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples.suo differ diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.csproj b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.csproj new file mode 100644 index 0000000..93d1f12 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.csproj @@ -0,0 +1,79 @@ + + + + Debug + AnyCPU + {c252feb5-a946-4202-b1d4-9916a0590387};{FAE04EC0-301F-11D3-BF4B-00C04F79EFBC} + + + + + {13E56BB3-CB08-4B05-BE52-0ACA0EA080E1} + Library + false + ApressExamples + v4.0 + false + + + 2 + + + true + full + false + bin\Debug\ + false + DEBUG;TRACE + 4 + true + + + false + true + bin\Release\ + false + TRACE + 4 + true + + + ApressExamples + + + + + + + + + + + + + + + + + + + + + + Content + + + Content + + + Content + + + + \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.csproj.user b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.csproj.user new file mode 100644 index 0000000..4bb0595 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.csproj.user @@ -0,0 +1,10 @@ + + + + + + + + + + \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.sqlproj b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.sqlproj new file mode 100644 index 0000000..48681ad --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.sqlproj @@ -0,0 +1,56 @@ + + + + + Debug + AnyCPU + ApressExamples + 2.0 + 4.1 + {be1f9cbf-1c1c-4b1d-b322-c48d02988eb4} + Microsoft.Data.Tools.Schema.Sql.Sql110DatabaseSchemaProvider + Database + + + ApressExamples + ApressExamples + 1033, CI + BySchemaAndSchemaType + True + v4.0 + CS + Properties + False + + + bin\Release\ + $(MSBuildProjectName).sql + False + pdbonly + true + false + true + prompt + 4 + + + bin\Debug\ + $(MSBuildProjectName).sql + false + true + full + false + true + true + prompt + 4 + + + + 10.0 + + + + + + \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.sqlproj.user b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.sqlproj.user new file mode 100644 index 0000000..ace9a86 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/ApressExamples.sqlproj.user @@ -0,0 +1,3 @@ + + + \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Complex.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Complex.cs new file mode 100644 index 0000000..d102290 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Complex.cs @@ -0,0 +1,245 @@ +using System; +using System.Data.SqlTypes; +using Microsoft.SqlServer.Server; +using System.Text.RegularExpressions; + +namespace Apress.Examples +{ + [Serializable] + [Microsoft.SqlServer.Server.SqlUserDefinedType + ( + Format.Native, + IsByteOrdered = true + )] + public struct Complex : INullable + { + + #region "Complex Number UDT Fields/Components" + + private bool m_Null; + public Double real; + public Double imaginary; + + #endregion + + #region "Complex Number Parsing, Constructor, and Methods/Properties" + + private static readonly Regex rx = new Regex( + "^(?[+-]?([0-9]+|[0-9]*\\.[0-9]+))[i|I]$|" + + "^(?[+-]?([0-9]+|[0-9]*\\.[0-9]+))$|" + + "^(?[+-]?([0-9]+|[0-9]*\\.[0-9]+))" + + "(?[+-]?([0-9]+|[0-9]*\\.[0-9]+))[i|I]$"); + + public static Complex Parse(SqlString s) + { + Complex u = new Complex(); + if (s.IsNull) + u = Null; + else + { + MatchCollection m = rx.Matches(s.Value); + if (m.Count == 0) + throw (new FormatException("Invalid Complex Number Format.")); + String real_str = m[0].Groups["Real"].Value; + String imaginary_str = m[0].Groups["Imaginary"].Value; + if (real_str == "" && imaginary_str == "") + throw (new FormatException("Invalid Complex Number Format.")); + if (real_str == "") + u.real = 0.0; + else + u.real = Convert.ToDouble(real_str); + if (imaginary_str == "") + u.imaginary = 0.0; + else + u.imaginary = Convert.ToDouble(imaginary_str); + } + return u; + } + + public override String ToString() + { + String sign = ""; + if (this.imaginary >= 0.0) + sign = "+"; + return this.real.ToString() + sign + this.imaginary.ToString() + "i"; + } + + public bool IsNull + { + get + { + return m_Null; + } + } + + public static Complex Null + { + get + { + Complex h = new Complex(); + h.m_Null = true; + return h; + } + } + + public Complex(Double r, Double i) + { + this.real = r; + this.imaginary = i; + this.m_Null = false; + } + + #endregion + + #region "Useful Complex Number Constants" + + // The property "i" is the Complex number 0 + 1i. Defined here because + // it is useful in some calculations + + public static Complex i + { + get + { + return new Complex(0, 1); + } + } + + // The property "Pi" is the Complex representation of the number + // Pi (3.141592... + 0i) + + public static Complex Pi + { + get + { + return new Complex(Math.PI, 0); + } + } + + // The property "One" is the Complex number representation of the + // number 1 (1 + 0i) + + public static Complex One + { + get + { + return new Complex(1, 0); + } + } + + #endregion + + #region "Complex Number Basic Operators" + + // Complex number addition + + public static Complex operator +(Complex n1, Complex n2) + { + Complex u; + if (n1.IsNull || n2.IsNull) + u = Null; + else + u = new Complex(n1.real + n2.real, n1.imaginary + n2.imaginary); + return u; + } + + // Complex number subtraction + + public static Complex operator -(Complex n1, Complex n2) + { + Complex u; + if (n1.IsNull || n2.IsNull) + u = Null; + else + u = new Complex(n1.real - n2.real, n1.imaginary - n2.imaginary); + return u; + } + + // Complex number multiplication + + public static Complex operator *(Complex n1, Complex n2) + { + Complex u; + if (n1.IsNull || n2.IsNull) + u = Null; + else + u = new Complex((n1.real * n2.real) - (n1.imaginary * n2.imaginary), + (n1.real * n2.imaginary) + (n2.real * n1.imaginary)); + return u; + } + + // Complex number division + + public static Complex operator /(Complex n1, Complex n2) + { + Complex u; + if (n1.IsNull || n2.IsNull) + u = Null; + else + { + if (n2.real == 0.0 && n2.imaginary == 0.0) + throw new DivideByZeroException + ("Complex Number Division By Zero Exception."); + u = new Complex(((n1.real * n2.real) + + (n1.imaginary * n2.imaginary)) / + ((Math.Pow(n2.real, 2) + Math.Pow(n2.imaginary, 2))), + ((n1.imaginary * n2.real) - (n1.real * n2.imaginary)) / + ((Math.Pow(n2.real, 2) + Math.Pow(n2.imaginary, 2)))); + } + return u; + } + + // Unary minus operator + + public static Complex operator -(Complex n1) + { + Complex u; + if (n1.IsNull) + u = Null; + else + u = new Complex(-n1.real, -n1.imaginary); + return u; + } + + #endregion + + #region "Exposed Mathematical Basic Operator Methods" + + // Add complex number n2 to n1 + + public static Complex CAdd(Complex n1, Complex n2) + { + return n1 + n2; + } + + // Subtract complex number n2 from n1 + + public static Complex Sub(Complex n1, Complex n2) + { + return n1 - n2; + } + + // Multiply complex number n1 * n2 + + public static Complex Mult(Complex n1, Complex n2) + { + return n1 * n2; + } + + // Divide complex number n1 by n2 + + public static Complex Div(Complex n1, Complex n2) + { + return n1 / n2; + } + + // Returns negated complex number + + public static Complex Neg(Complex n1) + { + return -n1; + } + + #endregion + + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/EmailAddressTrigger.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/EmailAddressTrigger.cs new file mode 100644 index 0000000..320441c --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/EmailAddressTrigger.cs @@ -0,0 +1,63 @@ +using System; +using System.Data; +using System.Data.SqlClient; +using Microsoft.SqlServer.Server; +using System.Text.RegularExpressions; +using System.Transactions; // you need to add the reference. Right-click on Project and add reference, SQL Server tab, System.Transactions for framework 4.0.0.0 + +namespace Apress.Examples +{ + public partial class Triggers + { + private static readonly Regex email_pattern = new Regex + ( + // Everything before the @ sign (the "local part") + "^[a-z0-9!#$%&'*+/=?^_`{|}~-]+(?:\\.[a-z0-9!#$%&'*+/=?^_`{|}~-]+)*" + + + // Subdomains after the @ sign + "@(?:[a-z0-9](?:[a-z0-9-]*[a-z0-9])?\\.)+" + + + // Top-level domains + "(?:[a-z]{2}|com|org|net|gov|mil|biz|info|mobi|name|aero|jobs|museum)\\b$" + ); + + // Enter existing table or view for the target and uncomment the attribute line + [Microsoft.SqlServer.Server.SqlTrigger(Name = "EmailAddressTrigger", Target = "[Person].[EmailAddress]", Event = "FOR INSERT, UPDATE")] + public static void EmailAddressTrigger() + { + SqlTriggerContext tContext = SqlContext.TriggerContext; + + // Retrieve the connection that the trigger is using. + using (SqlConnection cn + = new SqlConnection(@"context connection=true")) + { + SqlCommand cmd; + SqlDataReader r; + + cn.Open(); + + cmd = new SqlCommand(@"SELECT EmailAddress FROM INSERTED", cn); + r = cmd.ExecuteReader(); + try + { + while (r.Read()) + { + if (!email_pattern.IsMatch(r.GetString(0).ToLower())) + { + Transaction.Current.Rollback(); + } + } + } + catch (SqlException ex) + { + // Catch the expected exception. + } + finally + { + r.Close(); + cn.Close(); + } + } + } + } +} \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/EmailUDF.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/EmailUDF.cs new file mode 100644 index 0000000..61fd406 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/EmailUDF.cs @@ -0,0 +1,35 @@ +using System.Data.SqlTypes; +using System.Text.RegularExpressions; + +namespace Apress.Examples +{ + public static class UDFExample + { + private static readonly Regex email_pattern = new Regex + ( + // Everything before the @ sign (the "local part") + "^[a-z0-9!#$%&'*+/=?^_`{|}~-]+(?:\\.[a-z0-9!#$%&'*+/=?^_`{|}~-]+)*" + + + // Subdomains after the @ sign + "@(?:[a-z0-9](?:[a-z0-9-]*[a-z0-9])?\\.)+" + + + // Top-level domains + "(?:[a-z]{2}|com|org|net|gov|mil|biz|info|mobi|name|aero|jobs|museum)\\b$" + ); + + [Microsoft.SqlServer.Server.SqlFunction + ( + IsDeterministic = true + )] + public static SqlBoolean EmailMatch(SqlString input) + { + SqlBoolean result = new SqlBoolean(); + if (input.IsNull) + result = SqlBoolean.Null; + else + result = (email_pattern.IsMatch(input.Value.ToLower()) == true) + ? SqlBoolean.True : SqlBoolean.False; + return result; + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/GetEnvironmentVars.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/GetEnvironmentVars.cs new file mode 100644 index 0000000..5960109 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/GetEnvironmentVars.cs @@ -0,0 +1,43 @@ +using System; +using System.Collections; +using System.Data; + +using System.Data.SqlClient; +using System.Data.SqlTypes; +using Microsoft.SqlServer.Server; +namespace Apress.Examples +{ + public partial class SampleProc + { + [Microsoft.SqlServer.Server.SqlProcedure()] + public static void GetEnvironmentVars() + { + try + { + SortedList environment_list = new SortedList(); + foreach (DictionaryEntry de in Environment.GetEnvironmentVariables()) + { + environment_list[de.Key] = de.Value; + } + + SqlDataRecord record = new SqlDataRecord ( + new SqlMetaData("VarName", SqlDbType.NVarChar, 1024), + new SqlMetaData("VarValue", SqlDbType.NVarChar, 4000) + ); + SqlContext.Pipe.SendResultsStart(record); + foreach (DictionaryEntry de in environment_list) + { + record.SetValue(0, de.Key); + record.SetValue(1, de.Value); + SqlContext.Pipe.SendResultsRow(record); + } + + SqlContext.Pipe.SendResultsEnd(); + } + catch (Exception ex) + { + SqlContext.Pipe.Send(ex.Message); + } + } + } +}; diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Median.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Median.cs new file mode 100644 index 0000000..ed0d8c3 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Median.cs @@ -0,0 +1,101 @@ +using System; +using System.Collections.Generic; +using System.Data; +using System.Data.SqlTypes; +using System.Runtime.InteropServices; +using Microsoft.SqlServer.Server; + +namespace Apress.Examples { + [Serializable] + [Microsoft.SqlServer.Server.SqlUserDefinedAggregate ( + Format.UserDefined, + IsNullIfEmpty = true, + MaxByteSize = -1 )] + [StructLayout(LayoutKind.Sequential)] + + public struct Median : IBinarySerialize + { + List temp; // List of numbers + + public void Init() + { + // Create new list of double numbers + this.temp = new List(); + } + + public void Accumulate(SqlDouble number) + { + if (!number.IsNull) // Skip over NULLs + { + this.temp.Add(number.Value); // If number is not NULL, add it to list + } + } + + public void Merge(Median group) + { + // Merge two sets of numbers + this.temp.InsertRange(this.temp.Count, group.temp); + } + + public SqlDouble Terminate() { + SqlDouble result = SqlDouble.Null; // Default result to NULL + this.temp.Sort(); // Sort list of numbers + + int first, second; // Indexes to middle two numbers + + if (this.temp.Count % 2 == 1) + { + // If there is an odd number of values get the middle number twice + first = this.temp.Count / 2; + second = first; + } + else + { + // If there is an even number of values get the middle two numbers + first = this.temp.Count / 2 - 1; + second = first + 1; + } + + if (this.temp.Count > 0) // If there are numbers, calculate median + { + // Calculate median as average of middle number(s) + result = (SqlDouble)( this.temp[first] + this.temp[second] ) / 2.0; + } + + return result; + } + + #region IBinarySerialize Members + + // Custom serialization read method + public void Read(System.IO.BinaryReader r) + { + // Create a new list of double values + this.temp = new List(); + + // Get the number of values that were serialized + int j = r.ReadInt32(); + + // Loop and add each serialized value to the list + for (int i = 0; i < j; i++) + { + this.temp.Add(r.ReadDouble()); + } + } + + // Custom serialization write method + public void Write(System.IO.BinaryWriter w) + { + // Write the number of values in the list + w.Write(this.temp.Count); + + // Write out each value in the list + foreach (double d in this.temp) + { + w.Write(d); + } + } + + #endregion + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/PostDeployScript.sql b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/PostDeployScript.sql new file mode 100644 index 0000000..5f28270 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/PostDeployScript.sql @@ -0,0 +1 @@ + \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/PreDeployScript.sql b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/PreDeployScript.sql new file mode 100644 index 0000000..5f28270 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/PreDeployScript.sql @@ -0,0 +1 @@ + \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Properties/AssemblyInfo.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Properties/AssemblyInfo.cs new file mode 100644 index 0000000..f94ab64 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Properties/AssemblyInfo.cs @@ -0,0 +1,31 @@ +using System.Reflection; +using System.Runtime.CompilerServices; +using System.Runtime.InteropServices; +using System.Data.Sql; + +// General Information about an assembly is controlled through the following +// set of attributes. Change these attribute values to modify the information +// associated with an assembly. +[assembly: AssemblyTitle("ApressExamples")] +[assembly: AssemblyDescription("")] +[assembly: AssemblyConfiguration("")] +[assembly: AssemblyCompany("Microsoft")] +[assembly: AssemblyProduct("ApressExamples")] +[assembly: AssemblyCopyright("Copyright © Microsoft 2012")] +[assembly: AssemblyTrademark("")] +[assembly: AssemblyCulture("")] + +[assembly: ComVisible(false)] + +// +// Version information for an assembly consists of the following four values: +// +// Major Version +// Minor Version +// Build Number +// Revision +// +// You can specify all the values or you can default the Revision and Build Numbers +// by using the '*' as shown below: +[assembly: AssemblyVersion("1.0.*")] + diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Range.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Range.cs new file mode 100644 index 0000000..4608084 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Range.cs @@ -0,0 +1,57 @@ +using System; +using System.Data; +using System.Data.SqlClient; +using System.Data.SqlTypes; +using Microsoft.SqlServer.Server; + +namespace Apress.Examples { + [Serializable] + [Microsoft.SqlServer.Server.SqlUserDefinedAggregate(Format.Native)] + + public struct Range + { + SqlDouble min, max; + + public void Init() { + min = SqlDouble.Null; + max = SqlDouble.Null; + } + + public void Accumulate(SqlDouble value) + { + if (!value.IsNull) { + if (min.IsNull || value < min) + { + min = value; + } + + if (max.IsNull || value > max) + { + max = value; + } + } + } + + public void Merge(Range group) + { + if (min.IsNull || (!group.min.IsNull && group.min < min)) + { + min = group.min; + } + if (max.IsNull || (!group.max.IsNull && group.max > max)) + { + max = group.max; + } + } + + public SqlDouble Terminate() { + SqlDouble result = SqlDouble.Null; + if (!min.IsNull && !max.IsNull) + { + result = max - min; + } + + return result; + } + } +} \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Test Scripts/Test.sql b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Test Scripts/Test.sql new file mode 100644 index 0000000..8367fff --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/Test Scripts/Test.sql @@ -0,0 +1,34 @@ +-- Examples for queries that exercise different SQL objects implemented by this assembly + +----------------------------------------------------------------------------------------- +-- Stored procedure +----------------------------------------------------------------------------------------- +-- exec StoredProcedureName + + +----------------------------------------------------------------------------------------- +-- User defined function +----------------------------------------------------------------------------------------- +-- select dbo.FunctionName() + + +----------------------------------------------------------------------------------------- +-- User defined type +----------------------------------------------------------------------------------------- +-- CREATE TABLE test_table (col1 UserType) +-- +-- INSERT INTO test_table VALUES (convert(uri, 'Instantiation String 1')) +-- INSERT INTO test_table VALUES (convert(uri, 'Instantiation String 2')) +-- INSERT INTO test_table VALUES (convert(uri, 'Instantiation String 3')) +-- +-- select col1::method1() from test_table + + + +----------------------------------------------------------------------------------------- +-- User defined type +----------------------------------------------------------------------------------------- +-- select dbo.AggregateName(Column1) from Table1 + + +select 'To run your project, please edit the Test.sql file in your project. This file is located in the Test Scripts folder in the Solution Explorer.' diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/YahooRSS.cs b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/YahooRSS.cs new file mode 100644 index 0000000..0081dc1 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ApressExamples/ApressExamples/YahooRSS.cs @@ -0,0 +1,44 @@ +using System; +using System.Collections; +using System.Data.SqlTypes; +using Microsoft.SqlServer.Server; +using System.Xml; + +namespace Apress.Examples +{ + public partial class YahooRSS + { + + [Microsoft.SqlServer.Server.SqlFunction( + IsDeterministic = false, + DataAccess = DataAccessKind.None, + TableDefinition = "title nvarchar(256)," + + "link nvarchar(256), " + + "pubdate datetime, " + + "description nvarchar(max)", + FillRowMethodName = "GetRow") + ] + public static IEnumerable GetYahooNews() + { + XmlTextReader xmlsource = + new XmlTextReader("http://rss.news.yahoo.com/rss/topstories"); + XmlDocument newsxml = new XmlDocument(); + newsxml.Load(xmlsource); + xmlsource.Close(); + return newsxml.SelectNodes("//rss/channel/item"); + } + private static void GetRow( + Object o, + out SqlString title, + out SqlString link, + out SqlDateTime pubdate, + out SqlString description) + { + XmlElement element = (XmlElement)o; + title = element.SelectSingleNode("./title").InnerText; + link = element.SelectSingleNode("./link").InnerText; + pubdate = DateTime.Parse(element.SelectSingleNode("./pubDate").InnerText); + description = element.SelectSingleNode("./description").InnerText; + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch14/ch14.sql b/Pro T-SQL 2012 Programmer's Guide/Ch14/ch14.sql new file mode 100644 index 0000000..6ec5e01 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch14/ch14.sql @@ -0,0 +1,149 @@ +-------------------------------------------------------------------------- +-- Listing 14-1. Registering a CLR Integration Assembly with SQL Server -- +-------------------------------------------------------------------------- +EXEC sp_configure 'CLR Enabled'; +RECONFIGURE; + +CREATE ASSEMBLY ApressExamples +AUTHORIZATION dbo +FROM N'C:\MyApplication\ Apress.Examples.DLL' +WITH PERMISSION_SET = SAFE; +GO + +--------------------------------------------------------- +-- Listing 14-3. Creating CLR UDF from Assembly Method -- +--------------------------------------------------------- +CREATE FUNCTION dbo.EmailMatch (@input nvarchar(4000)) +RETURNS bit +WITH EXECUTE AS CALLER +AS +EXTERNAL NAME ApressExamples.[Apress.Examples.UDFExample].EmailMatch +GO + +------------------------------------------------------------------------ +-- Listing 14-4. Validating E-mail Addresses with Regular Expressions -- +------------------------------------------------------------------------ +SELECT + 'nospam-123@yahoo.com' AS Email, + dbo.EmailMatch (N'nospam-123@yahoo.com') AS Valid +UNION +SELECT + '123@456789', + dbo.EmailMatch('123@456789') +UNION + SELECT 'BillyG@HOTMAIL.COM', + dbo.EmailMatch('BillyG@HOTMAIL.COM'); +GO + +----------------------------------------------------------------------- +-- Listing 14-6. CREATE ASSEMBLY with EXTERNAL_ACCESS Permission Set -- +----------------------------------------------------------------------- +CREATE ASSEMBLY ApressExample +AUTHORIZATION dbo +FROM N'C:\MyApplication\ Apress.Example.DLL' +WITH PERMISSION_SET = EXTERNAL_ACCESS; +GO + +-------------------------------------------------- +-- Listing 14-7. Querying a CLR Integration TVF -- +-------------------------------------------------- +CREATE FUNCTION dbo.GetYahooNews() +RETURNS TABLE(title nvarchar(256), link nvarchar(256), pubdate datetime, description nvarchar(max)) +AS EXTERNAL NAME ApressExamples.[Apress.Examples.YahooRSS].GetYahooNews +GO + +SELECT + title, + link, + pubdate, + description +FROM dbo.GetYahooNews(); +GO + +------------------------------------------------------------------ +-- Listing 14-9. Executing the GetEnvironmentVars CLR Procedure -- +------------------------------------------------------------------ +CREATE PROCEDURE dbo.GetEnvironmentVars +AS EXTERNAL NAME ApressExamples.[Apress.Examples.SampleProc].GetEnvironmentVars; +GO + +EXEC dbo.GetEnvironmentVars; +GO + +----------------------------------------------------------- +-- Listing 14-11. Retrieving Statistical Ranges with UDA -- +----------------------------------------------------------- +CREATE AGGREGATE Range (@value float) RETURNS float +EXTERNAL NAME ApressExamples.[Apress.Examples.Range]; +GO + +SELECT + ProductID, + dbo.Range(UnitPrice) AS UnitPriceRange +FROM Sales.SalesOrderDetail +WHERE UnitPrice > 0 +GROUP BY ProductID; +GO + +------------------------------------------------------------- +-- Listing 14-13. Calculating Median Unit Price with a UDA -- +------------------------------------------------------------- +CREATE AGGREGATE dbo.Median (@value float) RETURNS float +EXTERNAL NAME ApressExamples.[Apress.Examples.Median]; +GO + +SELECT + ProductID, + dbo.Median(UnitPrice) AS MedianUnitPrice +FROM Sales.SalesOrderDetail +GROUP BY ProductID; +GO + +------------------------------------------------------------------------------ +-- Listing 14-17. Creation of the CLR Trigger to Validate an E-mail Address -- +------------------------------------------------------------------------------ +CREATE TRIGGER atr_Person_EmailAddress_ValidateEmail +ON Person.EmailAddress +AFTER INSERT, UPDATE +AS EXTERNAL NAME ApressExamples.[Apress.Examples.Triggers].EmailAddressTrigger; +GO + +------------------------------------------------------ +-- Listing 14-18. Setting an Invalid E-mail Address -- +------------------------------------------------------ +UPDATE Person.EmailAddress +SET EmailAddress = 'pro%sql@apress@com' +WHERE EmailAddress = 'dylan0@adventure-works.com'; +GO + +------------------------------------------------------------------ +-- Listing 14-19. UPDATE Statement Modified to Handle the Error -- +------------------------------------------------------------------ +BEGIN TRY + UPDATE Person.EmailAddress + SET EmailAddress = 'pro%sql@apress@com' + WHERE EmailAddress = 'dylan0@adventure-works.com'; +END TRY +BEGIN CATCH + IF ERROR_NUMBER() = 3991 + RAISERROR('invalid email address', 16, 10) +END CATCH +GO + +---------------------------------------------------------------- +-- Listing 14-20. T-SQL Trigger to Validate an E-mail Address -- +---------------------------------------------------------------- +CREATE TRIGGER atr_Person_EmailAddress_ValidateEmail +ON Person.EmailAddress +AFTER INSERT, UPDATE +AS BEGIN + IF @@ROWCOUNT = 0 RETURN + + IF EXISTS (SELECT * FROM inserted WHERE dbo.EmailMatch(EmailAddress) = 0) + BEGIN + RAISERROR('an email is invalid', 16, 10) + ROLLBACK TRANSACTION + END + +END; +GO \ No newline at end of file diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-01.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-01.cs new file mode 100644 index 0000000..fecd021 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-01.cs @@ -0,0 +1,52 @@ +Listing 15-1. SqlDataReader Sample +using System; +using System.Data.SqlClient; + +namespace Apress.Examples +{ + class Listing15_1 + { + static void Main(string[] args) + { + string sqlconnection = @"DATA SOURCE=SQL2012;" + + "INITIAL CATALOG=AdventureWorks;" + + "INTEGRATED SECURITY=SSPI;"; + + string sqlcommand = "SELECT " + + " DepartmentId, " + + " Name, " + + " GroupName " + + " FROM HumanResources.Department " + + " ORDER BY DepartmentId"; + + try + { + connection = new SqlConnection(sqlconnection); + connection.Open(); + command = new SqlCommand(sqlcommand, connection); + datareader = command.ExecuteReader(); + + while (datareader.Read()) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}", + datareader["DepartmentId"].ToString(), + datareader["Name"].ToString(), + datareader["GroupName"].ToString() + ); + } + } + catch (SqlException ex) + { + Console.WriteLine(ex.Message); + } + finally + { + connection.Close(); + } + Console.Write("Press a Key to Continue..."); + Console.ReadKey(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-02.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-02.cs new file mode 100644 index 0000000..8ee6564 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-02.cs @@ -0,0 +1,58 @@ +Listing 15-2. Using SqlDataReader to Fill a DataSet +using System; +using System.Data; +using System.Data.SqlClient; + +namespace Apress.Examples +{ + class Listing15_2 + { + static void Main(string[] args) + { + string sqlconnection = @"DATA SOURCE=SQL2012;" + + "INITIAL CATALOG=AdventureWorks;" + + "INTEGRATED SECURITY=SSPI;"; + + string sqlcommand = "SELECT " + + " DepartmentId, " + + " Name, " + + " GroupName " + + " FROM HumanResources.Department " + + " ORDER BY DepartmentId"; + + SqlDataAdapter adapter = null; + DataSet dataset = null; + + try + { + adapter = new SqlDataAdapter(sqlcommand, sqlconnection); + dataset = new DataSet(); + adapter.Fill(dataset); + + foreach (DataRow row in dataset.Tables[0].Rows) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}", + row["DepartmentId"].ToString(), + row["Name"].ToString(), + row["GroupName"].ToString() + ); + } + } + catch (SqlException ex) + { + Console.WriteLine(ex.Message); + } + finally + { + if (dataset != null) + dataset.Dispose(); + if (adapter != null) + adapter.Dispose(); + } + Console.Write("Press a Key to Continue..."); + Console.ReadKey(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-03.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-03.cs new file mode 100644 index 0000000..0769d06 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-03.cs @@ -0,0 +1,61 @@ +Listing 15-3. Parameterized SQL Query +using System; +using System.Data; +using System.Data.SqlClient; + +namespace Apress.Examples +{ + class Listing15_3 + { + static void Main(string[] args) + { + + string name = "SMITH"; + string sqlconnection = @"SERVER=SQL2012; " + + "INITIAL CATALOG=AdventureWorks; " + + "INTEGRATED SECURITY=SSPI;"; + + string sqlcommand = "SELECT " + + " BusinessEntityID, " + + " FirstName, " + + " MiddleName, " + + " LastName " + + "FROM Person.Person " + + "WHERE LastName = @name"; + + SqlConnection connection = null; + SqlCommand command = null; + SqlDataReader datareader = null; + + try + { + connection = new SqlConnection(sqlconnection); + connection.Open(); + command = new SqlCommand(sqlcommand, connection); + command.Parameters.Add("@name", SqlDbType.NVarChar, 50).Value = name; + datareader = command.ExecuteReader(); + while (datareader.Read()) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}\t{3}", + datareader["BusinessEntityID"].ToString(), + datareader["LastName"].ToString(), + datareader["FirstName"].ToString(), + datareader["MiddleName"].ToString() + ); + } + } + catch (Exception ex) + { + Console.WriteLine(ex.Message); + } + finally + { + connection.Close(); + } + Console.WriteLine("Press any key..."); + Console.ReadKey(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-04.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-04.cs new file mode 100644 index 0000000..b0648e7 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-04.cs @@ -0,0 +1,9 @@ +SqlCommand command = new SqlCommand + ( + "CREATE TABLE #temp " + + " ( " + + " Id INT NOT NULL PRIMARY KEY, " + + " Name NVARCHAR(50) " + + " );", connection + ); +command.ExecuteNonQuery(); diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-05.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-05.cs new file mode 100644 index 0000000..770edec --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-05.cs @@ -0,0 +1,6 @@ +SqlCommand command = new SqlCommand + ( + "SELECT COUNT(*) " + + "FROM Person.Person;", sqlconnection + ); +Object count = command.ExecuteScalar(); diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-06.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-06.cs new file mode 100644 index 0000000..30b9193 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-06.cs @@ -0,0 +1,68 @@ +using System; +using System.Data; +using System.Data.SqlClient; +using System.Xml; + +namespace Apress.Examples +{ + class Listing15_6 + { + static void Main(string[] args) + { + string name = "SMITH"; + string sqlconnection = @"SERVER=SQL2012; " + + "INITIAL CATALOG=AdventureWorks; " + + "INTEGRATED SECURITY=SSPI;"; + + string sqlcommand = "SELECT " + + " BusinessEntityID, " + + " FirstName, " + + " COALESCE(MiddleName, '') AS MiddleName, " + + " LastName " + + "FROM Person.Person " + + "WHERE LastName = @name " + + "FOR XML AUTO;"; + + SqlConnection connection = null; + SqlCommand command = null; + XmlReader xmlreader = null; + + try + { + connection = new SqlConnection(sqlconnection); + connection.Open(); + command = new SqlCommand(sqlcommand, connection); + SqlParameter par = command.Parameters.Add("@name", SqlDbType.NVarChar, + 50); + par.Value = name; + xmlreader = command.ExecuteXmlReader(); + while (xmlreader.Read()) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}\t{3}", + xmlreader["BusinessEntityID"].ToString(), + xmlreader["LastName"].ToString(), + xmlreader["FirstName"].ToString(), + xmlreader["MiddleName"].ToString() + ); + } + } + catch (Exception ex) + { + Console.WriteLine(ex.Message); + } + finally + { + if (xmlreader != null) + xmlreader.Close(); + if (command != null) + command.Dispose(); + if (connection != null) + connection.Dispose(); + } + Console.WriteLine("Press any key..."); + Console.ReadKey(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-07.sql b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-07.sql new file mode 100644 index 0000000..ecb27ec --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-07.sql @@ -0,0 +1,12 @@ +------------------------------------------------------ +-- Listing 15-7. Creating the ZipCodes Target Table -- +------------------------------------------------------ +CREATE TABLE dbo.ZipCodes +( + ZIP CHAR(5) NOT NULL PRIMARY KEY, + Latitude NUMERIC(8, 4) NOT NULL, + Longitude NUMERIC(8, 4) NOT NULL, + City NVARCHAR(50) NOT NULL, + State CHAR(2) NOT NULL +) +GO diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-08.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-08.cs new file mode 100644 index 0000000..3ba3acb --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-08.cs @@ -0,0 +1,104 @@ +using System; +using System.Data; +using System.Data.SqlClient; +using System.Data.SqlTypes; +using System.Diagnostics; +using System.IO; +using System.Globalization; + +namespace Apress.Example +{ + class Listing15_8 + { + static string sqlconnection = "DATA SOURCE=SQL2012; " + + "INITIAL CATALOG=AdventureWorks; " + + "INTEGRATED SECURITY=SSPI;"; + + static string sourcefile = "c:\\ZIPCodes.txt"; + + static DataTable loadtable = null; + + static void Main(string[] args) + { + Stopwatch clock = new Stopwatch(); + clock.Start(); + int rowcount = DoImport(); + clock.Stop(); + Console.WriteLine("{0} Rows Imported in {1} Seconds.", + rowcount, (clock.ElapsedMilliseconds / 1000.0)); + Console.WriteLine("Press a Key..."); + Console.ReadKey(); + } + + static int DoImport() + { + using (SqlBulkCopy bulkcopier = new SqlBulkCopy(sqlconnection)) + { + bulkcopier.DestinationTableName = "dbo.ZIPCodes"; + try + { + LoadSourceFile(); + bulkcopier.WriteToServer(loadtable); + } + catch (SqlException ex) + { + Console.WriteLine(ex.Message); + } + } + return loadtable.Rows.Count; + } + + static void LoadSourceFile() + { + loadtable = new DataTable(); + DataColumn loadcolumn = new DataColumn(); + DataRow loadrow = null; + + loadcolumn.DataType = typeof(SqlString); + loadcolumn.ColumnName = "ZIP"; + loadcolumn.Unique = true; + loadtable.Columns.Add(loadcolumn); + + loadcolumn = new DataColumn(); + loadcolumn.DataType = typeof(SqlDecimal); + loadcolumn.ColumnName = "Latitude"; + loadcolumn.Unique = false; + loadtable.Columns.Add(loadcolumn); + + loadcolumn = new DataColumn(); + loadcolumn.DataType = typeof(SqlDecimal); + loadcolumn.ColumnName = "Longitude"; + loadcolumn.Unique = false; + loadtable.Columns.Add(loadcolumn); + + loadcolumn = new DataColumn(); + loadcolumn.DataType = typeof(SqlString); + loadcolumn.ColumnName = "City"; + loadcolumn.Unique = false; + loadtable.Columns.Add(loadcolumn); + + loadcolumn = new DataColumn(); + loadcolumn.DataType = typeof(SqlString); + loadcolumn.ColumnName = "State"; + loadcolumn.Unique = false; + loadtable.Columns.Add(loadcolumn); + + using (StreamReader stream = new StreamReader(sourcefile)) + { + string record = stream.ReadLine(); + while (record != null) + { + string[] cols = record.Split('\t'); + loadrow = loadtable.NewRow(); + loadrow["ZIP"] = cols[0]; + loadrow["Latitude"] = decimal.Parse(cols[1], CultureInfo.InvariantCulture); + loadrow["Longitude"] = decimal.Parse(cols[2], CultureInfo.InvariantCulture); + loadrow["City"] = cols[3]; + loadrow["State"] = cols[4]; + loadtable.Rows.Add(loadrow); + record = stream.ReadLine(); + } + } + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-09.sql b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-09.sql new file mode 100644 index 0000000..a09eafb --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-09.sql @@ -0,0 +1,10 @@ +----------------------------------------------- +-- Listing 15-9. Verifying Bulk Copy Results -- +----------------------------------------------- +SELECT + ZIP, + Latitude, + Longitude, + City, +State FROM dbo.ZipCodes; + diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-10.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-10.cs new file mode 100644 index 0000000..53d883d --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-10.cs @@ -0,0 +1,109 @@ +using System; +using System.Data; +using System.Data.SqlClient; + +namespace Apress.Examples +{ + class MARS + { + static string sqlconnection = @"SERVER=SQL2012; " + + "INITIAL CATALOG=AdventureWorks; " + + "INTEGRATED SECURITY=SSPI; " + + "MULTIPLEACTIVERESULTSETS=true; "; + + static string sqlcommand1 = "SELECT " + + " DepartmentID, " + + " Name, " + + " GroupName " + + "FROM HumanResources.Department; "; + + static string sqlcommand2 = "SELECT " + + " ShiftID, " + + " Name, " + + " StartTime, " + + " EndTime " + + "FROM HumanResources.Shift; "; + + static SqlConnection connection = null; + static SqlCommand command1 = null; + static SqlCommand command2 = null; + static SqlDataReader datareader1 = null; + static SqlDataReader datareader2 = null; + + static void Main(string[] args) + { + try + { + connection = new SqlConnection(sqlconnection); + connection.Open(); + command1 = new SqlCommand(sqlcommand1, connection); + command2 = new SqlCommand(sqlcommand2, connection); + datareader1 = command1.ExecuteReader(); + datareader2 = command2.ExecuteReader(); + int i = 0; + + Console.WriteLine("==========="); + Console.WriteLine("Departments"); + Console.WriteLine("==========="); + while (datareader1.Read() && i++ < 3) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}", + datareader1["DepartmentID"].ToString(), + datareader1["Name"].ToString(), + datareader1["GroupName"].ToString() + ); + } + + Console.WriteLine("======"); + Console.WriteLine("Shifts"); + Console.WriteLine("======"); + while (datareader2.Read()) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}\t{3}", + datareader2["ShiftID"].ToString(), + datareader2["Name"].ToString(), + datareader2["StartTime"].ToString(), + datareader2["EndTime"].ToString() + ); + } + + Console.WriteLine("======================"); + Console.WriteLine("Departments, Continued"); + Console.WriteLine("======================"); + while (datareader1.Read()) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}", + datareader1["DepartmentID"].ToString(), + datareader1["Name"].ToString(), + datareader1["GroupName"].ToString() + ); + } + } + catch (SqlException ex) + { + Console.WriteLine(ex.Message); + } + finally + { + if (datareader1 != null) + datareader1.Dispose(); + if (datareader2 != null) + datareader2.Dispose(); + if (command1 != null) + command1.Dispose(); + if (command2 != null) + command2.Dispose(); + if (connection != null) + connection.Dispose(); + } + Console.WriteLine("Press a key to end..."); + Console.ReadKey(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-12.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-12.cs new file mode 100644 index 0000000..02434b9 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-12.cs @@ -0,0 +1,30 @@ +using System; +using System.Linq; + +namespace Apress.Examples +{ + class Listing15_12 + { + static void Main(string[] args) + { + AdventureWorksDataContext db = new AdventureWorksDataContext(); + db.Log = Console.Out; + + var query = from p in db.Persons + select p; + + foreach (Person p in query) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}", + p.FirstName, + p.MiddleName, + p.LastName + ); + } + Console.WriteLine("Press a key to continue..."); + Console.ReadKey(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-18.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-18.cs new file mode 100644 index 0000000..5d95db9 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-18.cs @@ -0,0 +1,41 @@ +using System; +using System.Linq; + +namespace Apress.Examples +{ + class Listing15_18 + { + static void Main(string[] args) + { + AdventureWorksDataContext db = new AdventureWorksDataContext(); + db.Log = Console.Out; + + var query = from p in db.Persons + join e in db.EmailAddresses + on p.BusinessEntityID equals e.BusinessEntityID + where p.LastName.Contains("SMI") + orderby p.LastName, p.FirstName + select new + { + LastName = p.LastName, + FirstName = p.FirstName, + MiddleName = p.MiddleName, + EmailAddress = e.EmailAddress1 + }; + + foreach (var q in query) + { + Console.WriteLine + ( + "{0}\t{1}\t{2}\t{3}", + q.FirstName, + q.MiddleName, + q.LastName, + q.EmailAddress + ); + } + Console.WriteLine("Press a key to continue..."); + Console.ReadKey(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-20.sql b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-20.sql new file mode 100644 index 0000000..74bfd43 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-20.sql @@ -0,0 +1,5 @@ +--------------------------------------------------------------------------------------------- +-- Listing 15-20. Creating a Computed Column to Show Hierarchyid Representation in the EDM -- +--------------------------------------------------------------------------------------------- +ALTER TABLE [HumanResources].[Employee] +ADD OrganizationNodeString AS OrganizationNode.ToString() PERSISTED; diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-21.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-21.cs new file mode 100644 index 0000000..9f8293a --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-21.cs @@ -0,0 +1,33 @@ +using System; +using System.Linq; +using System.Text; + +namespace EntityFramework +{ + class Program + { + static void Main(string[] args) + { + using (var ctx = new AdventureWorksEntitiesEmployee()) + { + var qry = from e in ctx.Employee + where e.Gender == "F" + select new + { + e.Person.FirstName, + e.Person.LastName, + e.BirthDate + }; + + foreach (var emp in qry.Take(5)) { + Console.WriteLine("{0} {1}, born {2}", + emp.FirstName, + emp.LastName, + emp.BirthDate.ToLongDateString() + ); + } + Console.Read(); + } + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-23.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-23.cs new file mode 100644 index 0000000..67eed85 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-23.cs @@ -0,0 +1,25 @@ +using System; +using System.Linq; +using System.Text; + +namespace EntityFramework +{ + class Program + { + static void Main(string[] args) + { + using (var ctx = new AdventureWorksEntitiesEmployee()) + { + foreach (var emp in ctx.Employee.Where(e => e.Gender == "F").Take(5)) + { + Console.WriteLine("{0} {1}, born {2}", + emp.Person.FirstName, + emp.Person.LastName, + emp.BirthDate.ToLongDateString() + ); + } + Console.Read(); + } + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-24.cs b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-24.cs new file mode 100644 index 0000000..bd05ce7 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch15/ch15-24.cs @@ -0,0 +1,31 @@ +using System; +using System.Linq; +using System.Text; + +namespace EntityFramework +{ + class Program + { + static void Main(string[] args) + { + using (var ctx = new AdventureWorksEntitiesEmployee()) + { + var newP = new BusinessEntity { + ModifiedDate = DateTime.Now, + rowguid = Guid.NewGuid() + }; + + Console.WriteLine("BusinessEntityID before insert : {0}", + newP.BusinessEntityID); + + ctx.BusinessEntities.AddObject(newP); + ctx.SaveChanges(); + + Console.WriteLine("BusinessEntityID after insert : {0}", + newP.BusinessEntityID); + } + + Console.Read(); + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-01.cs b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-01.cs new file mode 100644 index 0000000..c33bc16 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-01.cs @@ -0,0 +1,45 @@ +using System; +using System.Data.SqlClient; +using System.Text; + +namespace localdbClient +{ + class Program + { + static void Main(string[] args) + { + try + { + SqlConnectionStringBuilder builder = + new SqlConnectionStringBuilder(@"Server=(localdb)\SQLSrvWebApp1;Integrated Security=true"); + + builder.AttachDBFilename = @"C:\Users\Administrator\Documents\AdventureWorksLT2012_Data.mdf"; + + Console.WriteLine("connection string = " + builder.ConnectionString); + + using (SqlConnection cn = new SqlConnection(builder.ConnectionString)) + { + cn.Open(); + SqlCommand cmd = cn.CreateCommand(); + cmd.CommandText = "SELECT Name FROM sys.tables;"; + SqlDataReader rd = cmd.ExecuteReader(); + + while(rd.Read()) + { + Console.WriteLine(rd.GetValue(0)); + } + rd.Close(); + cn.Close(); + } + Console.WriteLine("Press any key to finish."); + Console.ReadLine(); + } + catch (Exception ex) + { + Console.WriteLine(ex.Message); + Console.WriteLine("Press any key to finish."); + Console.ReadLine(); + } + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-02.cs b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-02.cs new file mode 100644 index 0000000..d48b741 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-02.cs @@ -0,0 +1,13 @@ +private void ExecuteSP() +{ + SqlConnectionStringBuilder cnString = new SqlConnectionStringBuilder(); + cnString.DataSource = @”(localdb)\v11.0”; + cnString.IntegratedSecurity = true; + + using (SqlConnection cn = new SqlConnection(cnString.ConnectionString)) + { + cn.Open(); + SqlCommand cmd = new SqlCommand("EXEC dbo.GetProducts", cn); + cmd.ExecuteReader(); + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-03.cs b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-03.cs new file mode 100644 index 0000000..64261be --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-03.cs @@ -0,0 +1,13 @@ +private async Task ExecuteSP() +{ + SqlConnectionStringBuilder cnString = new SqlConnectionStringBuilder(); + cnString.DataSource = @”(localdb)\v11.0”; + cnString.IntegratedSecurity = true; + + using (SqlConnection cn = new SqlConnection(cnString.ConnectionString)) + { + await cn.OpenAsync(); + SqlCommand cmd = new SqlCommand("EXEC dbo.GetProducts", cn); + await cmd.ExecuteReaderAsync(); + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-04.java b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-04.java new file mode 100644 index 0000000..821e49f --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-04.java @@ -0,0 +1,49 @@ +import java.sql.*; + +public class ApressExample { + + public static void main(String[] args) { + + String connectionUrl = "jdbc:sqlserver://SQL2012;integratedSecurity=true;databaseName=AdventureWorks;failoverPartner=SQL2012B"; + Connection cn = null; + String qry = "SELECT TOP 10 FirstName, LastName FROM Person.Contact"; + + try { + cn = DriverManager.getConnection(connectionUrl); + runQuery(cn, qry); + } catch (SQLException se) { + try { + System.out.println("Connection to principal server failed, trying the mirror server."); + cn = DriverManager.getConnection(connectionUrl); + runQuery(cn, qry); + } catch (Exception e) { + e.printStackTrace(); + } + } catch (Exception e) { + e.printStackTrace(); + } finally { + if (cn != null) try { cn.close(); } catch(Exception e) { } + } + } + + private static void runQuery(Connection cn, String SQL) { + Statement stmt = null; + ResultSet rs = null; + + try { + stmt = cn.createStatement(); + rs = stmt.executeQuery(SQL); + + while (rs.next()) { + System.out.println(rs.getString(0)); + } + rs.close(); + stmt.close(); + } catch (Exception e) { + e.printStackTrace(); + } finally { + if (rs != null) try { rs.close(); } catch(Exception e) {} + if (stmt != null) try { stmt.close(); } catch(Exception e) {} + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-05.cs b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-05.cs new file mode 100644 index 0000000..9fab67d --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-05.cs @@ -0,0 +1,22 @@ +using System; +using System.Collections.Generic; +using System.Data.Services; +using System.Data.Services.Common; +using System.Linq; +using System.ServiceModel.Web; +using System.Web; + +namespace WCFDataServicesSample +{ + public class ProductPhotoDataService : DataService + { + // This method is called only once to initialize service-wide policies. + public static void InitializeService(DataServiceConfiguration config) + { + config.SetEntitySetAccessRule("Products", EntitySetRights.AllRead); + config.SetEntitySetAccessRule("ProductPhotoes", EntitySetRights.AllRead); + config.SetEntitySetAccessRule("ProductProductPhotoes", EntitySetRights.AllRead); + config.DataServiceBehavior.MaxProtocolVersion = DataServiceProtocolVersion.V2; + } + } +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-06.cs b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-06.cs new file mode 100644 index 0000000..44f631c --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch16/ch16-06.cs @@ -0,0 +1,70 @@ +using System; +using System.Collections.Generic; +using System.Linq; +using System.Web; +using System.Web.UI; +using System.Web.UI.WebControls; +using WCFdsClient.PhotoServiceReference; +using System.Data.Services.Client; + +namespace WCFdsClient +{ + public partial class _Default : System.Web.UI.Page + { + protected void Page_Load(object sender, EventArgs e) + { + PopulateDropDown(); + } + + private void PopulateDropDown() + { + AdventureWorksEntities ctx = new AdventureWorksEntities( + new Uri ("http://localhost:59560/ProductPhotoDataService.svc") + ); + + var qry = from p in ctx.Products + where p.FinishedGoodsFlag + orderby p.Name + select p; + + foreach (Product p in qry) { + ProductDropDown.Items.Add(new ListItem(p.Name, p.ProductID.ToString())); + } + + string id = ProductDropDown.SelectedValue; + UpdateImage(id); + } + + private void UpdateImage(string id) { + ProductImage.ImageUrl = string.Format("GetImage.aspx?id={0}", id); + } + + protected void ProductDropDownlist_SelectedIndexChanged(object sender, EventArgs e) + { + string id = ProductDropDown.SelectedValue; + + AdventureWorksEntities ctx = new AdventureWorksEntities( + new Uri("http://localhost:59560/ProductPhotoDataService.svc") + ); + + var qry = from p in ctx.Products + where p.ProductID == Convert.ToInt32(id) + select p; + + //DataServiceOuery qry = ctx.CreateOuery(string.Format("/Product({0})", id)); + + foreach (Product p in qry) + { + TableProduct.Rows[0].Cells[1].Text = p.Class; + TableProduct.Rows[1].Cells[1].Text = p.Color; + TableProduct.Rows[2].Cells[1].Text = p.Size + " " + p.SizeUnitMeasureCode; + TableProduct.Rows[3].Cells[1].Text = p.Weight + " " + p.WeightUnitMeasureCode; + TableProduct.Rows[4].Cells[1].Text = p.ListPrice.ToString(); + TableProduct.Rows[5].Cells[1].Text = p.ProductNumber; + } + UpdateImage(id); + } + + } + +} diff --git a/Pro T-SQL 2012 Programmer's Guide/Ch18/9781430245964_Natarajan_Ch18_PerformanceTuning.sql b/Pro T-SQL 2012 Programmer's Guide/Ch18/9781430245964_Natarajan_Ch18_PerformanceTuning.sql new file mode 100644 index 0000000..adc6eb6 --- /dev/null +++ b/Pro T-SQL 2012 Programmer's Guide/Ch18/9781430245964_Natarajan_Ch18_PerformanceTuning.sql @@ -0,0 +1,364 @@ +/*Listing 18 - 1. Creating a Narrow Table */ +CREATE TABLE dbo.SmallRows +( +Id int NOT NULL, +LastName nchar(50) NOT NULL, +FirstName nchar(50) NOT NULL, +MiddleName nchar(50) NULL +); +INSERT INTO dbo.SmallRows +( +Id, +LastName, +FirstName, +MiddleName +) +SELECT +BusinessEntityID, +LastName, +FirstName, +MiddleName +FROM Person.Person; + +/*Listing 18 - 2. Looking at Data Allocations for the SmallRows Table */ +SELECT +sys.fn_PhysLocFormatter(%%physloc%%) AS [Row_Locator], +Id +FROM dbo.SmallRows; + +/*Listing 18 - 3. Creating a Table with Wide Rows */ +CREATE TABLE dbo.LargeRows +( +Id int NOT NULL, +LastName nchar(600) NOT NULL, +FirstName nchar(600) NOT NULL, +MiddleName nchar(600) NULL +); +INSERT INTO dbo.LargeRows +( +Id, +LastName, +FirstName, +MiddleName +) +SELECT +BusinessEntityID, +LastName, +FirstName, +MiddleName +FROM Person.Person; +SELECT +sys.fn_PhysLocFormatter(%%physloc%%) AS [Row_Locator], +Id +FROM dbo.LargeRows; + +/*Listing 18 - 4. I/O Comparison of Narrow and Wide Tables */ +SET STATISTICS IO ON; +SELECT +Id, +LastName, +FirstName, +MiddleName +FROM dbo.SmallRows; +SELECT +Id, +LastName, +FirstName, +MiddleName +FROM dbo.LargeRows; + +/*Listing 18 - 5. Estimating Row Compression Space Savings */ +EXEC sp_estimate_data_compression_savings 'Production', +'TransactionHistory', +NULL, +NULL, +'ROW'; + +/*Listing 18 - 5. Estimating Row Compression Space Savings */ +EXEC sp_estimate_data_compression_savings 'Production', +'TransactionHistory', +NULL, +NULL, +'ROW'; + +/*Listing 18 - 5. Estimating Row Compression Space Savings */ +EXEC sp_estimate_data_compression_savings 'Production', +'TransactionHistory', +NULL, +NULL, +'ROW'; + +/*Listing 18 - 8. Estimating Data Compression Savings with Page Compression */ +EXEC sp_estimate_data_compression_savings 'Person', +'Person', +NULL, +NULL, +'PAGE'; + +/*Listing 18 - 9. Applying Page Compression to the Person.Person Table */ +ALTER TABLE Person.Person REBUILD +WITH (DATA_COMPRESSION = PAGE); + +/*Listing 18 - 10. Pivot Query that Generates Columns with Many NULLs */ +SELECT +CustomerID, +[HL Road Frame - Black, 58], +[HL Road Frame - Red, 58], +[HL Road Frame - Red, 62], +[HL Road Frame - Red, 44], +[HL Road Frame - Red, 48], +[HL Road Frame - Red, 52], +[HL Road Frame - Red, 56], +[LL Road Frame - Black, 58] +FROM +( +SELECT soh.CustomerID, p.Name AS ProductName, +COUNT +( +CASE WHEN sod.LineTotal IS NULL THEN NULL +ELSE 1 +END +) AS NumberOfItems +FROM Sales.SalesOrderHeader soh +INNER JOIN Sales.SalesOrderDetail sod +ON soh.SalesOrderID = sod.SalesOrderID +INNER JOIN Production.Product p +ON sod.ProductID = p.ProductID +GROUP BY +soh.CustomerID, +sod.ProductID, +p.Name +) src +PIVOT +( +SUM(NumberOfItems) FOR ProductName +IN +( +"HL Road Frame - Black, 58", +"HL Road Frame - Red, 58", +"HL Road Frame - Red, 62", +"HL Road Frame - Red, 44", +"HL Road Frame - Red, 48", +"HL Road Frame - Red, 52", +"HL Road Frame - Red, 56", +"LL Road Frame - Black, 58" +) +) AS pvt; + +/*Listing 18 - 11. Creating Sparse and Nonsparse Tables */ +CREATE TABLE NonSparseTable +( +CustomerID int NOT NULL PRIMARY KEY, +"HL Road Frame - Black, 58" int NULL, +"HL Road Frame - Red, 58" int NULL, +"HL Road Frame - Red, 62" int NULL, +"HL Road Frame - Red, 44" int NULL, +"HL Road Frame - Red, 48" int NULL, +"HL Road Frame - Red, 52" int NULL, +"HL Road Frame - Red, 56" int NULL, +"LL Road Frame - Black, 58" int NULL +); +CREATE TABLE SparseTable +( +CustomerID int NOT NULL PRIMARY KEY, +"HL Road Frame - Black, 58" int SPARSE NULL, +"HL Road Frame - Red, 58" int SPARSE NULL, +"HL Road Frame - Red, 62" int SPARSE NULL, +"HL Road Frame - Red, 44" int SPARSE NULL, +"HL Road Frame - Red, 48" int SPARSE NULL, +"HL Road Frame - Red, 52" int SPARSE NULL, +"HL Road Frame - Red, 56" int SPARSE NULL, +"LL Road Frame - Black, 58" int SPARSE NULL +); + +/*Listing 18 - 12. Calculating the Space Savings of Sparse Columns */ +EXEC sp_spaceused N'NonSparseTable'; +EXEC sp_spaceused N'SparseTable'; + +/*Listing 18 - 13. Creating and Populating a Table with a Sparse Column Set */ +CREATE TABLE Production.SparseProduct +( +ProductID int NOT NULL PRIMARY KEY, +Name dbo.Name NOT NULL, +ProductNumber nvarchar(25) NOT NULL, +Color nvarchar(15) SPARSE NULL, +Size nvarchar(5) SPARSE NULL, +SizeUnitMeasureCode nchar(3) SPARSE NULL, +WeightUnitMeasureCode nchar(3) SPARSE NULL, +Weight decimal(8, 2) SPARSE NULL, +Class nchar(2) SPARSE NULL, +Style nchar(2) SPARSE NULL, +SellStartDate datetime NOT NULL, +SellEndDate datetime SPARSE NULL, +DiscontinuedDate datetime SPARSE NULL, +SparseColumnSet xml COLUMN_SET FOR ALL_SPARSE_COLUMNS +); +GO +INSERT INTO Production.SparseProduct +( +ProductID, +Name, +ProductNumber, +Color, +Size, +SizeUnitMeasureCode, +WeightUnitMeasureCode, +Weight, +Class, +Style, +SellStartDate, +SellEndDate, +DiscontinuedDate +) +SELECT +ProductID, +Name, +ProductNumber, +Color, +Size, +SizeUnitMeasureCode, +WeightUnitMeasureCode, +Weight, +Class, +Style, +SellStartDate, +SellEndDate, +DiscontinuedDate +FROM Production.Product; +GO + + +/*Listing 18 - 14. Querying XML Sparse Column Set as XML */ +SELECT TOP(7) +ProductID, +SparseColumnSet FROM Production.SparseProduct; + +/*Listing 18 - 15. Querying Sparse Column Sets by Name */ +SELECT +ProductID, +Name, +ProductNumber, +SellStartDate, +Color, +Class +FROM Production.SparseProduct +WHERE ProductID IN (1, 317); + +/*Listing 18 - 16. Query Requiring a Bookmark Lookup */ +SELECT +BusinessEntityID, +LastName, +FirstName, +MiddleName, +Title FROM Person.Person WHERE LastName = N'Duffy'; + +/*Listing 18 - 17. Query Using a Covering Index */ +CREATE NONCLUSTERED INDEX [IX_Covering_Person_LastName_FirstName_MiddleName] ON +[Person].[Person] +( +[LastName] ASC, +[FirstName] ASC, +[MiddleName] ASC +) INCLUDE (Title) +WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, SORT_IN_TEMPDB = OFF, DROP_EXISTING = OFF, +ONLINE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY] +GO + +/*Listing 18 - 18. Creating and Testing a Filtered Index on the Production.Product Table */ +CREATE NONCLUSTERED INDEX IX_Product_Size +ON Production.Product +( +Size, +SizeUnitMeasureCode ) +WHERE Size IS NOT NULL; +GO +SELECT +ProductID, +Size, +SizeUnitMeasureCode FROM Production.Product WHERE Size = 'L'; +GO + +/*Listing 18 - 19. Script to Demonstrate Waits */ +use adventureworks +go +CREATE TABLE [dbo].[waitsdemo]( +[Id] [int] NOT NULL, +[LastName] [nchar](600) NOT NULL, +[FirstName] [nchar](600) NOT NULL, +[MiddleName] [nchar](600) NULL +) ON [PRIMARY] +GO +declare @id int = 1 +while (@id < = 50000) +begin +insert into waitsdemo +select @id,'Foo', 'User',NULL +SET @id = @id + 1 +end + +/*Listing 18 - 20. DMV to Query Current Processes and Waiting Tasks */ +--List waiting user requests +SELECT +er.session_id, er.wait_type, er.wait_time, +er.wait_resource, er.last_wait_type, +er.command,et.text,er.blocking_session_id +FROM sys.dm_exec_requests AS er +JOIN sys.dm_exec_sessions AS es +ON es.session_id = er.session_id +AND es.is_user_process = 1 +CROSS APPLY sys.dm_exec_sql_text(er.sql_handle) AS et +GO +--List waiting user tasks +SELECT +wt.waiting_task_address, wt.session_id, wt.wait_type, +wt.wait_duration_ms, wt.resource_description +FROM sys.dm_os_waiting_tasks AS wt +JOIN sys.dm_exec_sessions AS es +ON wt.session_id = es.session_id +AND es.is_user_process = 1 +GO +-- List user tasks +SELECT +t.session_id, t.request_id, t.exec_context_id, +t.scheduler_id, t.task_address, +t.parent_task_address +FROM sys.dm_os_tasks AS t +JOIN sys.dm_exec_sessions AS es +ON t.session_id = es.session_id +AND es.is_user_process = 1 +GO + + +/*Listing 18 - 21. Extended Event Session Script to Troubleshoot Login Timeouts */ +CREATE EVENT SESSION [Troubleshoot page split] ON SERVER +ADD EVENT sqlserver.page_split( +ACTION(sqlserver.client_app_name,sqlserver.database_id,sqlserver.database_name,sqlserver.plan_ +handle,sqlserver.server_instance_name,sqlserver.server_principal_name,sqlserver.server_principal_ +sid,sqlserver.session_id,sqlserver.session_nt_username,sqlserver.sql_text,sqlserver.transaction_ +id,sqlserver.username)), +ADD EVENT sqlserver.rpc_completed( +ACTION(sqlserver.client_app_name,sqlserver.database_id,sqlserver.database_name,sqlserver.plan_ +handle,sqlserver.server_instance_name,sqlserver.server_principal_name,sqlserver.server_principal_ +sid,sqlserver.session_id,sqlserver.session_nt_username,sqlserver.sql_text,sqlserver.transaction_ +id,sqlserver.username)), +ADD EVENT sqlserver.rpc_starting( +ACTION(sqlserver.client_app_name,sqlserver.database_id,sqlserver.database_name,sqlserver.plan_ +handle,sqlserver.server_instance_name,sqlserver.server_principal_name,sqlserver.server_principal_ +sid,sqlserver.session_id,sqlserver.session_nt_username,sqlserver.sql_text,sqlserver.transaction_ +id,sqlserver.username)), +ADD EVENT sqlserver.sp_statement_completed( +ACTION(sqlserver.client_app_name,sqlserver.database_id,sqlserver.database_name,sqlserver.plan_ +handle,sqlserver.server_instance_name,sqlserver.server_principal_name,sqlserver.server_principal_ +sid,sqlserver.session_id,sqlserver.session_nt_username,sqlserver.sql_text,sqlserver.transaction_ +id,sqlserver.username)), +ADD EVENT sqlserver.sp_statement_starting( +ACTION(sqlserver.client_app_name,sqlserver.database_id,sqlserver.database_name,sqlserver.plan_ +handle,sqlserver.server_instance_name,sqlserver.server_principal_name,sqlserver.server_principal_ +sid,sqlserver.session_id,sqlserver.session_nt_username,sqlserver.sql_text,sqlserver.transaction_ +id,sqlserver.username)) +ADD TARGET package0.event_file(SET filename = N'C:\Temp\Troubleshoot page split.xel') +WITH (MAX_MEMORY = 4096 +KB,EVENT_RETENTION_MODE = ALLOW_SINGLE_EVENT_LOSS,MAX_DISPATCH_LATENCY = 30 SECONDS,MAX_EVENT_SIZE = 0 +KB,MEMORY_PARTITION_MODE = NONE,TRACK_CAUSALITY = OFF,STARTUP_STATE = OFF) +GO + diff --git a/README.md b/README.md new file mode 100644 index 0000000..76c4f16 --- /dev/null +++ b/README.md @@ -0,0 +1,15 @@ +#Apress Source Code + +This repository accompanies [*Pro T-SQL 2012 Programmer's Guide*](http://www.apress.com/9781430245964) by Michael Coles, Scott Shaw, Jay Natarajan, and Rudi Bruchez (Apress, 2012). + +![Cover image](9781430245964.jpg) + +Download the files as a zip using the green button, or clone the repository to your machine using Git. + +##Releases + +Release v1.0 corresponds to the code in the published book, without corrections or updates. + +##Contributions + +See the file Contributing.md for more information on how you can contribute to this repository. diff --git a/contributing.md b/contributing.md new file mode 100644 index 0000000..f6005ad --- /dev/null +++ b/contributing.md @@ -0,0 +1,14 @@ +# Contributing to Apress Source Code + +Copyright for Apress source code belongs to the author(s). However, under fair use you are encouraged to fork and contribute minor corrections and updates for the benefit of the author(s) and other readers. + +## How to Contribute + +1. Make sure you have a GitHub account. +2. Fork the repository for the relevant book. +3. Create a new branch on which to make your change, e.g. +`git checkout -b my_code_contribution` +4. Commit your change. Include a commit message describing the correction. Please note that if your commit message is not clear, the correction will not be accepted. +5. Submit a pull request. + +Thank you for your contribution! \ No newline at end of file