-
Recent Posts
Archives
Categories
Author Archives: Robert
SQL Server Transactional replication error
This week, the replication of the subscription of one of our most important databases stopped working. The distribution agent job stopped. In the job history, it had logged the following error: The distribution agent failed to create temporary files in … Continue reading
Posted in Uncategorized
Leave a comment
Running processes including job step name
The normal output of sys.dm_exec_sessions (or sysprocesses) will tell you that a job is running, but it will hide the name of the job behind a heximal representation of the job_id, not the job_id as displayed in sysjobs. This script … Continue reading
Posted in T-SQL
2 Comments
Get-AzDataFactoryPipeline: a misleading error
A few weeks back, I wanted to start an Azure Data Factory pipeline using PowerShell. It was the first time I tried that, and I thought it would be pretty simple: get the correct pipeline using Get-AzDataFactoryPipeline, supply all the … Continue reading
Posted in Azure Data Factory, Powershell
Leave a comment
Code samples for my book on Querying data with Transact-SQL (MCSA 70-761), chapter 3
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 |
USE TestDB GO /* Create database programmability objects by using Transact-SQL */ -- views -- 001 WITH o AS ( SELECT * FROM Sales.Orders) SELECT * FROM o -- 002 CREATE VIEW vwEmployeeFirstName AS SELECT FirstName FROM Employees; -- 003 SELECT * FROM vwEmployeefirstname; -- 004 GO CREATE OR ALTER VIEW vwEmployeeFirstName AS SELECT FirstName FROM Employees; -- 005 CREATE VIEW vwEmployeesEngineering AS SELECT * FROM dbo.Employees WHERE Department = 'Engineering' GO SELECT * FROM vwEmployeesEngineering -- 006 ALTER TABLE Employees ADD AdditionalColumn varchar(100) NULL GO CREATE OR ALTER VIEW vwEmployeesEngineering AS SELECT FirstName, LastName, AdditionalColumn FROM dbo.Employees WHERE Department = 'Engineering' GO SELECT * FROM vwEmployeesEngineering GO ALTER TABLE Employees DROP COLUMN AdditionalColumn GO SELECT * FROM vwEmployeesEngineering -- 007 CREATE OR ALTER VIEW vwEmployeesEngineering WITH SCHEMABINDING AS SELECT FirstName, LastName, AdditionalColumn FROM dbo.Employees WHERE Department = 'Engineering' -- 008 EXEC sp_refreshview 'vwEmployeesEngineering' -- 009 CREATE OR ALTER VIEW vwEmployeesEngineering WITH ENCRYPTION AS SELECT FirstName, LastName, AdditionalColumn FROM dbo.Employees WHERE Department = 'Engineering' -- 010 SELECT object_name(id), text FROM sys.syscomments -- 011 UPDATE vwEmployeesEngineering SET FirstName = 'Bobby' WHERE FirstName = 'Bob' -- 012 UPDATE vwEmployeesEngineering SET Department = 'Sales' WHERE FirstName = 'Bobby' -- 013 UPDATE dbo.Employees SET FirstName = 'Bob', Department = 'Engineering' WHERE FirstName = 'Bobby' GO CREATE OR ALTER VIEW vwEmployeesEngineering AS SELECT * FROM dbo.Employees WHERE Department = 'Engineering' WITH CHECK OPTION -- 014 INSERT INTO [dbo].[vwEmployeesEngineering] ([FirstName], [LastName], [Address], [Salary], [Department]) VALUES ('James' ,'Jameson' ,'Somewhere in Ireland' ,1000 ,'sales') -- 015 DELETE FROM vwEmployeesEngineering WHERE FirstName = 'James' -- 016 DROP VIEW IF EXISTS vwEmployeesEngineering /* Implement input and output parameters in stored procedures */ -- 017 CREATE OR ALTER PROC procGetEmployeeInformation AS BEGIN --explanation of what the stored proc does SET NOCOUNT ON; SELECT * FROM Employees; END -- 018 EXEC procGetEmployeeInformation -- 019 DROP PROC IF EXISTS procGetEmployeeInformation -- 020 CREATE PROC procGetEmployeeID @FirstName varchar(100) ,@LastName varchar(50) ,@Address varchar(100) AS BEGIN SELECT EmployeeID FROM Employees WHERE FirstName = @FirstName AND LastName = @LastName AND Address = @Address; END; -- 021 EXEC procGetEmployeeID @FirstName = 'Bob', @LastName = 'Jackson', @Address = 'Under the bridge' EXEC procGetEmployeeID 'Bob', 'Jackson', 'Under the bridge' -- 022 CREATE OR ALTER PROC procGetEmployeeID @FirstName varchar(100) ,@LastName varchar(50) ,@Address varchar(100) ,@EmployeeID tinyint OUTPUT AS BEGIN SELECT @EmployeeID = EmployeeID FROM Employees WHERE FirstName = @FirstName AND LastName = @LastName AND Address = @Address; END; -- 023 DECLARE @EmployeeID tinyint EXEC procGetEmployeeID 'Bob', 'Jackson', 'Under the bridge', @EmployeeID = @EmployeeID OUTPUT SELECT @EmployeeID -- 024 CREATE PROC procLogicalTest @parameter int AS BEGIN IF @parameter = 1 BEGIN EXEC proc1; END ELSE BEGIN EXEC proc2 END END; /* functions */ -- 025 CREATE FUNCTION dbo.fn_rand () RETURNS INT AS BEGIN RETURN RAND() END -- 026 CREATE OR ALTER FUNCTION dbo.fn_doubler (@a int) RETURNS INT AS BEGIN RETURN @a * 2 END -- 027 SELECT dbo.fn_doubler (18) -- 028 SELECT FirstName , LastName , dbo.fn_doubler(salary) as TwiceTheSalary FROM dbo.Employees -- 029 CREATE FUNCTION dbo.fn_GetListOfEmployees(@Department AS varchar(100)) RETURNS TABLE AS RETURN ( SELECT FirstName + ' ' + LastName AS FullName, Salary FROM Employees e WHERE e.Department = @Department ) -- 030 SELECT * FROM dbo.fn_GetListOfEmployees('Sales') -- 031 CREATE OR ALTER FUNCTION dbo.fn_name (...) RETURNS @return_table TABLE AS BEGIN --some statements --a statement to fill the table variable INSERT @return_table SELECT ... --return the table variable to the calling statement RETURN END -- 032 CREATE dbo.ManagersAllTheWayToTheTop (@employeeid tinyint) RETURNS @tbl_managers TABLE ( Name varchar(151) , Manager varchar(151) ,Level tinyint ) BEGIN WITH Employee_CTE AS ( SELECT EmployeeID, ManagerID, 0 as Level FROM Employees WHERE FirstName = 'Bob' UNION ALL SELECT e1.EmployeeID, e1.ManagerID, e2.level + 1 FROM Employees e1 INNER JOIN Employee_CTE e2 ON e1.EmployeeID = e2.ManagerID ) , Distinct_CTE AS ( SELECT DISTINCT EmployeeID, ManagerID, Level FROM Employee_CTE) INSERT INTO @tbl_managers SELECT e2.FirstName + ' ' + e2.LastName AS Name , e3.FirstName + ' ' + e3.LastName AS Manager, Level FROM Distinct_CTE e1 INNER JOIN Employees e2 ON e1.employeeID = e2.EmployeeID LEFT OUTER JOIN Employees e3 ON e1.ManagerID = e3.EmployeeID ORDER BY Level, Name RETURN END GO SELECT * FROM dbo.managersallthewaytothetop(1) DROP FUNCTION IF EXISTS dbo.ManagersAllTheWayToTheTop -- 033 CREATE OR ALTER FUNCTION dbo.fn_doubler (@a int) RETURNS INT AS BEGIN RETURN @a * 2 END GO SELECT OBJECTPROPERTYEX(OBJECT_ID('dbo.fn_doubler'), 'IsDeterministic') -- 034 CREATE OR ALTER FUNCTION dbo.fn_doubler (@a int) RETURNS INT WITH SCHEMABINDING AS BEGIN RETURN @a * 2 END GO SELECT OBJECTPROPERTYEX(OBJECT_ID('dbo.fn_doubler'), 'IsDeterministic') /* Implement error handling and transactions */ --For more information on isolation levels, see: https://docs.microsoft.com/en-us/sql/connect/jdbc/understanding-isolation-levels?view=sql-server-2016 -- 035 USE TestDB GO DROP TABLE IF EXISTS dbo.OrderLines DROP TABLE IF EXISTS dbo.Orders DROP TABLE IF EXISTS dbo.Customers GO CREATE TABLE dbo.Customers( CustomerID int IDENTITY(1,1) NOT NULL, FirstName varchar(100) NOT NULL, LastName varchar(100) NOT NULL, [Address] varchar(100) NOT NULL, PRIMARY KEY CLUSTERED (CustomerID) ) CREATE TABLE dbo.Orders( OrderID int IDENTITY(1,1) NOT NULL, CustomerID int NOT NULL, OrderDate datetime NOT NULL, SalesAmount money NOT NULL, PRIMARY KEY CLUSTERED (OrderID ) ) CREATE TABLE dbo.OrderLines( OrderID int NOT NULL, OrderLineID int IDENTITY(1,1) NOT NULL, Item varchar(100) NOT NULL, Amount int NOT NULL, LineAmount money NOT NULL, PRIMARY KEY CLUSTERED (OrderID, OrderLineID ) ) GO ALTER TABLE dbo.Orders ADD CONSTRAINT FK_customerID FOREIGN KEY (CustomerID) REFERENCES dbo.Customers(CustomerID) ALTER TABLE dbo.OrderLines ADD CONSTRAINT FK_OrderID FOREIGN KEY (OrderID) REFERENCES dbo.Orders(OrderID) -- 036 INSERT dbo.Customers VALUES ('Bob', 'Jackson', 'Main street 1, Dallas') -- 037 SET IMPLICIT_TRANSACTIONS ON INSERT dbo.Customers VALUES ('Frank', 'Smith', 'Second street 2, Miami') -- 038 SELECT * FROM Customers -- 039 SELECT * FROM Customers WITH (NOLOCK) -- 040 DBCC OPENTRAN(); -- 041 SELECT session_id, open_transaction_count FROM sys.dm_exec_sessions WHERE session_id > 50; -- 042 SELECT @@TRANCOUNT -- 043 COMMIT TRANSACTION -- 044 SET IMPLICIT_TRANSACTIONS OFF -- 045 BEGIN TRANSACTION INSERT dbo.Customers VALUES ('Joe', 'Johnson', 'Third Avenue 3, New York') COMMIT TRANSACTION -- 046 BEGIN TRAN MyTran WITH MARK 'StartOfTransaction' -- 047 ROLLBACK /* Nesting transactions */ -- 048 INSERT Orders (CustomerID, OrderDate, SalesAmount) VALUES (1, GETDATE(), 10.00) -- 049 UPDATE Orders SET SalesAmount = 10.00 BEGIN TRAN SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 BEGIN TRAN SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 BEGIN TRAN SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 COMMIT TRAN SELECT @@Trancount AS 'Transaction level' COMMIT TRAN SELECT @@Trancount AS 'Transaction level' COMMIT TRAN SELECT * FROM Orders WHERE orderid = 1 -- 050 UPDATE Orders SET SalesAmount = 10.00 BEGIN TRAN SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 BEGIN TRAN SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 BEGIN TRAN SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 COMMIT TRAN SELECT @@Trancount AS 'Transaction level' ROLLBACK TRAN --<<<< Only this line has changed SELECT @@Trancount AS 'Transaction level' COMMIT TRAN SELECT * FROM Orders WHERE orderid = 1 /* Named transaction */ -- 051 UPDATE Orders SET SalesAmount = 10.00 BEGIN TRAN MyFirstTransaction SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 BEGIN TRAN MySecondTransaction SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 BEGIN TRAN MyThirdTransaction SELECT @@Trancount AS 'Transaction level' UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 COMMIT TRAN MyThirdTransaction SELECT @@Trancount AS 'Transaction level' ROLLBACK TRAN MySecondTransaction SELECT @@Trancount AS 'Transaction level' COMMIT TRAN MyFirstTransaction SELECT * FROM Orders WHERE orderid = 1 -- 052 ROLLBACK TRAN /* savepoints */ -- 053 UPDATE Orders SET SalesAmount = 10.00 BEGIN TRAN UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 SAVE TRANSACTION MyFirstSavepoint UPDATE Orders SET SalesAmount = SalesAmount + 1 WHERE orderid = 1 ROLLBACK TRANSACTION MyFirstSavepoint COMMIT TRAN SELECT * FROM Orders WHERE orderid = 1 -- what is rolled back? -- 054 EXEC xp_cmdshell 'mkdir d:\Test_directory' -- 055 BEGIN TRAN EXEC xp_cmdshell 'mkdir d:\Test_directory' ROLLBACK -- 056 BEGIN TRAN CREATE DATABASE TooBad ROLLBACK -- 057 SET NOCOUNT ON DECLARE @MyToughVariable INT SET @MyToughVariable = 1 SELECT IDENT_CURRENT('Customers') AS 'Current identity' BEGIN TRAN SET @MyToughVariable = 2 SELECT @MyToughVariable AS 'Variable' CREATE TABLE MysteryTable (MysterID INT IDENTITY, Mystery VARCHAR(100)) INSERT MysteryTable VALUES ('Who killed Kennedy?') SELECT * FROM MysteryTable ALTER TABLE dbo.Customers ADD DateOfBirth DATETIME NULL INSERT dbo.Customers VALUES ('Serena', 'Baker', 'Broadway, New York', GETDATE()) SELECT * FROM Customers ROLLBACK TRAN SELECT @MyToughVariable AS 'Variable' SELECT IDENT_CURRENT('Customers') AS 'Current identity' SELECT * FROM dbo.Customers SELECT * FROM MysteryTable -- 058 SET XACT_ABORT ON -- 059 DROP TABLE IF EXISTS MysteryTable; -- application timeout example -- 060 USE TestDB GO SET XACT_ABORT ON BEGIN TRAN CREATE TABLE MysteryTable (MysterID INT IDENTITY, Mystery VARCHAR(100)) INSERT MysteryTable VALUES ('Who killed Kennedy?') WAITFOR DELAY '00:01' COMMIT TRAN -- 061 SELECT * FROM MysteryTable; /* foreign key error example */ -- 062 SET XACT_ABORT ON BEGIN TRAN DECLARE @Order_id INT INSERT Orders (CustomerID, OrderDate, SalesAmount) VALUES (2, GETDATE(), 50.00) SET @Order_id = @@IDENTITY INSERT OrderLines (OrderID, Item, Amount, LineAmount) VALUES (@Order_id , 'Bag of screws', 4, 10.00) INSERT OrderLines (OrderID, Item, Amount, LineAmount) VALUES (@Order_id + 1, 'Screwdriver', 1, 10.00) COMMIT /* Implement TRY…CATCH error handling with Transact-SQL */ -- 063 BEGIN TRY DECLARE @MyVariable INT SET @MyVariable = 5 SET @MyVariable = @MyVariable/0 PRINT 'This line of code will not be executed' END TRY BEGIN CATCH PRINT 'A useful error message' END CATCH -- 064 BEGIN TRY DECLARE @MyVariable INT; SET @MyVariable = 5; SET @MyVariable = @MyVariable/0; PRINT 'This line of code will not be executed'; END TRY BEGIN CATCH SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_SEVERITY() AS ErrorSeverity, ERROR_STATE() AS ErrorState, ISNULL(ERROR_PROCEDURE(), 'Not inside a stored proc') AS ErrorProcedure, ERROR_LINE() AS ErrorLine, ERROR_MESSAGE() AS ErrorMessage; END CATCH /* THROW */ -- 065 BEGIN TRY DECLARE @MyVariable INT; SET @MyVariable = 5; SET @MyVariable = @MyVariable/0; PRINT 'This line of code will not be executed'; END TRY BEGIN CATCH PRINT 'A useful error message'; THROW; PRINT 'This line of code will not be executed either'; END CATCH ; -- 066 THROW 50000, 'A useful error message', 0; -- 067 DECLARE @msg_number INT = 50000 ,@msg_text NVARCHAR(2048) = N'A useful error message' ,@msg_state TINYINT = 0; THROW @msg_number, @msg_text, @msg_state; -- 068 SET @msg_text = 'This error occurred on ' + CONVERT(varchar(19),getdate(), 20) + ', process id ' + CONVERT(varchar(10),@@SPID); -- 069 USE master; GO EXEC sp_addmessage @msgnum = 50001 ,@severity = 16 ,@msgtext = 'This error occurred on %s , process id %s.' ,@lang = 'us_english'; EXEC sp_addmessage @msgnum = 50001 ,@severity = 16 ,@msgtext = 'Dieser Fehler ist aufgetreten %1!,Prozess ID %2!' ,@lang = 'German'; GO -- 070 DECLARE @msg_number INT = 50001 ,@msg_text NVARCHAR(2048) ,@msg_state TINYINT = 0; SET LANGUAGE German; SET @msg_text = FORMATMESSAGE(50001, CONVERT(varchar(19),getdate(), 20), CONVERT(varchar(10),@@SPID)); THROW @msg_number, @msg_text, @msg_state; -- 071 DECLARE @msg_number INT = 50001 ,@msg_text NVARCHAR(2048) ,@msg_state TINYINT = 0; SET LANGUAGE us_english; SET @msg_text = FORMATMESSAGE(50001, CONVERT(varchar(19),getdate(), 20), CONVERT(varchar(10),@@SPID)); THROW @msg_number, @msg_text, @msg_state; /* RAISERROR */ -- 072 DECLARE @date varchar(19) = CONVERT(varchar(19),getdate(), 20) ,@process_id varchar(10) = CONVERT(varchar(10),@@SPID); RAISERROR (50001, 16, 1, @date, @process_id); GO DECLARE @date varchar(19) = CONVERT(varchar(19),getdate(), 20) ,@process_id varchar(10) = CONVERT(varchar(10),@@SPID); RAISERROR ('This error occurred on %s , process id %s.', 16, 1, @date, @process_id); GO DECLARE @date varchar(19) = CONVERT(varchar(19),getdate(), 20) ,@process_id varchar(10) = CONVERT(varchar(10),@@SPID) ,@msg_text nvarchar (100) = N'This error occurred on %s , process id %s.'; RAISERROR (@msg_text, 16, 1, @date, @process_id); GO -- 073 DECLARE @date varchar(19) = CONVERT(varchar(19),getdate(), 20) ,@process_id varchar(10) = CONVERT(varchar(10),@@SPID) ,@msg_text nvarchar (100) = N'This error occurred on %s , process id %s.'; RAISERROR (@msg_text, 20, 1, @date, @process_id) WITH LOG; GO -- 074 EXEC sp_dropmessage @msgnum = 50001, @lang = 'all'; -- 075 DROP TABLE IF EXISTS MysteryTable; DECLARE @date varchar(19) = CONVERT(varchar(19),getdate(), 20) ,@process_id varchar(10) = CONVERT(varchar(10),@@SPID); SET XACT_ABORT OFF; BEGIN TRAN CREATE TABLE MysteryTable (MysterID INT IDENTITY, Mystery VARCHAR(100)); INSERT MysteryTable VALUES ('Who killed Kennedy?'); THROW 50000, 'A useful error message', 0; --RAISERROR (50001, 16, 1, @date, @process_id); COMMIT GO SELECT * FROM MysteryTable; /* Implement transaction control in conjunction with error handling in stored procedures */ -- 076 CREATE PROCEDURE usp_my_stored_proc @MyVariable <data_type> AS BEGIN SET XACT_ABORT, NOCOUNT ON; BEGIN TRY BEGIN TRAN --Validate input parameter(s) IF @MyVariable ... --Actual work ... COMMIT TRAN END TRY BEGIN CATCH IF @@TRANCOUNT > 0 ROLLBACK TRAN -- error message, either THROW, RAISERROR or custom error logging code END CATCH END -- 077 CREATE PROC usp_inner_proc AS BEGIN SET XACT_ABORT ON BEGIN TRY BEGIN TRAN SELECT 5/0 COMMIT TRAN END TRY BEGIN CATCH ROLLBACK; THROW END CATCH END GO CREATE PROC usp_outer_proc AS BEGIN SET XACT_ABORT ON BEGIN TRY BEGIN TRAN EXEC usp_inner_proc COMMIT TRAN END TRY BEGIN CATCH ROLLBACK; THROW END CATCH END GO EXEC usp_outer_proc -- 078 ALTER PROC usp_outer_proc AS BEGIN SET XACT_ABORT ON BEGIN TRY BEGIN TRAN EXEC usp_inner_proc COMMIT TRAN END TRY BEGIN CATCH IF @@TRANCOUNT > 0 ROLLBACK; THROW END CATCH END -- 079 DROP PROC IF EXISTS usp_inner_proc DROP PROC IF EXISTS usp_outer_proc --For more information about error handling, read the eBook Defensive Database Programming with SQL Server, by Alex Kuznetsov, available for free at: https://www.red-gate.com/library/defensive-database-programming /* Implement data types and NULLs */ DECLARE @MyVariable DECIMAL(5,2) DECLARE @MyVariable FLOAT(n) -- 080 DECLARE @MyVariable real = 100.123456789 SELECT STR(@MyVariable, 6,2) --text DECLARE @MyVariable CHAR(4) = 'Text' DECLARE @MyVariable NCHAR(4) = N'Text' -- 081 DECLARE @MyVariable uniqueidentifier = NEWID() SELECT @MyVariable --rowversion -- 082 CREATE TABLE Table1 (Column1 smallint, Column2 rowversion) INSERT Table1 (Column1) VALUES (1) SELECT * FROM Table1 UPDATE Table1 SET Column1 = 2 SELECT * FROM Table1 --implicit conversion -- 083 DECLARE @MyVariable INT = '45' SET @MyVariable = @MyVariable + 10 IF @MyVariable > '50' PRINT 'Yep, it''s bigger.' -- 084 DECLARE @MyVariable VARCHAR(100) = 'My favourite number is ' SET @MyVariable = @MyVariable + 16 SELECT @MyVariable -- The complete data type precedence list: https://docs.microsoft.com/en-us/sql/t-sql/data-types/data-type-precedence-transact-sql?view=sql-server-2016 -- Implicit conversions: https://docs.microsoft.com/en-us/sql/t-sql/data-types/data-type-conversion-database-engine?view=sql-server-2016 -- 085 SELECT 2/5 SELECT 2000000000 + 2000000000 -- 086 SELECT 2000000000 + 4000000000 -- 087 DECLARE @MyVariable numeric(3,2) = 4.63 SELECT @MyVariable AS column1 INTO Type_check_table /* ISNULL versus COALESCE */ -- 088 DECLARE @MyNULLVariable VARCHAR(100) ,@MyNonNULLVariable VARCHAR(100) = 'Original value' SELECT ISNULL(@MyNULLVariable, 'Replacement value') ,ISNULL(@MyNonNULLVariable, 'Replacement value') -- 089 DECLARE @MyNULLVariable VARCHAR(100) ,@MyNonNULLVariable VARCHAR(100) = 'Original value' SELECT COALESCE(@MyNULLVariable, @MyNonNULLVariable, 'Replacement value') -- 090 SELECT CASE WHEN @MyNULLVariable IS NOT NULL THEN @MyNULLVariable WHEN @MyNonNULLVariable IS NOT NULL THEN @MyNonNULLVariable ELSE 'Replacement value' END -- 091 DECLARE @MyDateVariable date = '2018-10-05' ,@MyDateTimeVariable datetime = '2018-10-05 11:07' SELECT ISNULL(@MyDateVariable, @MyDateTimeVariable) , COALESCE(@MyDateVariable, @MyDateTimeVariable) -- 092 DROP TABLE IF EXISTS Type_check_table DECLARE @MyDateVariable date = '2018-10-05' SELECT ISNULL(@MyDateVariable, '2018-10-05 11:07') AS column1 ,ISNULL('2018-10-05 11:07', @MyDateVariable) AS column2 ,ISNULL(@MyDateVariable, @MyDateVariable) AS column3 ,ISNULL('2018-10-05 11:07', '2018-10-05 11:07') AS column4 INTO Type_check_table SELECT c.name, t.name, c.max_length, c.precision, c.scale, c.is_nullable FROM sys.columns c INNER JOIN sys.types t ON c.system_type_id = t.system_type_id WHERE object_id = object_id('Type_check_table') DROP TABLE IF EXISTS Type_check_table -- 093 SELECT * INTO Customers_copy FROM WideWorldImporters.sales.Customers SELECT * INTO orders_copy FROM WideWorldImporters.sales.orders -- 094 SELECT CustomerName ,ISNULL(( SELECT MAX(OrderDate) FROM Orders_copy o WHERE o.CustomerID = c.CustomerID), '1900-1-1') FROM Customers_copy c SELECT CustomerName ,COALESCE(( SELECT MAX(OrderDate) FROM Orders_copy o WHERE o.CustomerID = c.CustomerID), '1900-1-1') FROM Customers_copy c -- 095 SELECT CustomerName ,CASE WHEN ( SELECT MAX(OrderDate) FROM Orders_copy o WHERE o.CustomerID = c.CustomerID) IS NOT NULL THEN ( SELECT MAX(OrderDate) FROM Orders_copy o WHERE o.CustomerID = c.CustomerID) ELSE '1900-1-1' END FROM Customers_copy c |
Posted in Code samples, MCSA SQL 2016 70-761
Leave a comment
How I passed the exam AZ-900 Microsoft Azure Fundamentals
This week, I passed my first Azure exam: AZ-900 Microsoft Azure Fundamentals. As the name suggests, this is the most basic Azure exam, and therefore a nice place to start if you want to get certified in one of the … Continue reading
Posted in Uncategorized
Leave a comment
Dynamic PIVOT statement
My attempt to make a dynamic PIVOT statement. The table used is the same as the example in my 70-761 book. First, the @list_of_columns parameter is filled to create a list of columns, using COALESCE. Next a common table expression is … Continue reading
Posted in Uncategorized
Leave a comment
Convert MSDB job history to datetime
This script will get the job history for a particular job. The start time will be converted from integer to datetime. Works for job duration under 1000 hours. Since I’ve still got clients on SQL 2008, I can’t use the … Continue reading
Posted in Uncategorized
Leave a comment
Bonus questions for MCSA 70-761
The practice questions have been moved to a free course on my Teachable site: https://consigno.teachable.com
Posted in Books, MCSA SQL 2016 70-761
Leave a comment
Code samples for my book on Querying data with Transact-SQL (MCSA 70-761), chapter 2
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727 728 729 730 731 732 733 734 735 736 737 738 739 740 741 742 743 744 745 746 747 748 749 750 751 752 753 754 755 756 757 758 759 760 761 762 763 764 765 766 767 768 769 770 771 772 773 774 775 776 777 778 779 780 781 782 783 784 785 786 787 788 789 790 791 792 793 794 795 796 797 798 799 800 801 802 803 804 805 806 807 808 809 810 811 812 813 814 815 816 817 818 819 820 821 822 823 824 825 826 827 828 829 830 831 832 833 834 835 836 837 838 839 840 841 842 843 844 845 846 847 848 849 850 851 852 853 854 855 856 857 858 859 860 861 862 863 864 865 866 867 868 869 870 871 872 873 874 875 876 877 878 879 880 881 882 883 884 885 886 887 888 889 890 891 892 893 894 895 896 897 898 899 900 901 902 903 904 905 906 907 908 909 910 911 912 913 914 915 916 917 918 919 920 921 922 923 924 925 926 927 928 929 930 931 932 933 934 935 936 937 938 939 940 941 942 943 944 945 946 947 948 949 950 951 952 953 954 955 956 957 958 959 960 961 962 963 964 965 966 967 968 969 970 971 972 973 974 975 976 977 978 979 980 981 982 983 984 985 986 987 988 989 990 991 992 993 994 995 996 997 998 999 1000 1001 1002 1003 1004 1005 1006 1007 1008 1009 1010 1011 1012 1013 1014 1015 1016 1017 1018 1019 1020 1021 1022 1023 1024 1025 1026 1027 1028 1029 1030 1031 1032 1033 1034 1035 1036 1037 1038 1039 1040 1041 1042 1043 1044 1045 1046 1047 1048 1049 1050 1051 1052 1053 1054 1055 1056 1057 1058 1059 1060 1061 1062 1063 1064 1065 1066 1067 1068 1069 1070 1071 1072 1073 1074 1075 1076 1077 1078 1079 1080 1081 1082 1083 1084 1085 1086 1087 1088 1089 1090 1091 1092 1093 1094 1095 1096 1097 1098 1099 1100 1101 1102 1103 1104 1105 1106 1107 1108 1109 1110 1111 1112 1113 1114 1115 1116 1117 1118 1119 1120 1121 1122 1123 1124 1125 1126 1127 1128 1129 1130 1131 1132 1133 1134 1135 1136 1137 1138 1139 1140 1141 1142 1143 1144 1145 1146 1147 1148 1149 1150 1151 1152 1153 1154 1155 1156 1157 1158 1159 1160 1161 1162 1163 1164 1165 1166 1167 1168 1169 1170 1171 1172 1173 1174 1175 1176 1177 1178 1179 1180 1181 1182 1183 1184 1185 1186 1187 1188 1189 1190 1191 1192 1193 1194 1195 1196 1197 1198 1199 1200 1201 1202 1203 1204 1205 1206 1207 1208 1209 1210 1211 1212 1213 1214 1215 1216 1217 1218 1219 1220 1221 1222 1223 1224 1225 1226 1227 1228 1229 1230 1231 1232 1233 1234 1235 1236 1237 1238 1239 1240 1241 1242 1243 1244 1245 1246 1247 1248 1249 1250 1251 1252 1253 1254 1255 1256 1257 1258 1259 1260 1261 1262 1263 1264 1265 1266 1267 1268 1269 1270 1271 1272 1273 1274 1275 1276 1277 1278 1279 1280 1281 1282 1283 1284 1285 1286 1287 1288 1289 1290 1291 1292 1293 1294 1295 1296 1297 1298 1299 1300 1301 1302 1303 1304 1305 1306 1307 1308 1309 1310 1311 1312 1313 1314 1315 1316 1317 1318 1319 1320 1321 1322 1323 1324 1325 1326 1327 1328 1329 1330 1331 1332 1333 1334 1335 1336 1337 1338 1339 1340 1341 1342 1343 1344 1345 1346 1347 1348 1349 1350 1351 1352 1353 1354 1355 1356 1357 1358 1359 1360 1361 1362 1363 1364 1365 1366 1367 1368 1369 1370 1371 1372 1373 1374 1375 1376 1377 1378 1379 1380 1381 1382 1383 1384 1385 1386 1387 1388 1389 1390 1391 1392 1393 1394 1395 1396 1397 1398 1399 1400 1401 1402 1403 1404 1405 1406 1407 1408 1409 1410 1411 1412 1413 1414 1415 1416 1417 1418 1419 1420 1421 1422 1423 1424 1425 1426 1427 1428 1429 1430 1431 1432 1433 1434 1435 1436 |
USE WideWorldImporters; /* Query data by using subqueries and APPLY */ -- 001 -- simple subquery SELECT o.* FROM (SELECT * FROM Sales.Orders) o -- 002 SELECT * FROM [Application].[People] WHERE PreferredName IN ( SELECT CustomerName FROM sales.Customers ) -- 003 USE TestDB; SELECT * ,(SELECT AVG(salary) FROM dbo.Employees) AS average_salary FROM dbo.Employees -- 004 SELECT * FROM dbo.Employees WHERE Salary > (SELECT AVG(salary) FROM dbo.Employees) -- 005 -- correlated subquery SELECT * FROM dbo.Employees e1 WHERE Salary > ( SELECT AVG(salary) FROM Employees e2 WHERE e1.department = e2.department) -- 006 SELECT * FROM dbo.Employees e1 INNER JOIN (SELECT AVG(salary) AS avg_salary, department FROM dbo.employees GROUP BY department) e2 ON e1.Department = e2.Department WHERE salary > e2.avg_salary -- 007 SELECT * , (SELECT AVG(salary) FROM Employees e2 WHERE e1.department = e2.Department) FROM Employees e1 WHERE Salary > ( SELECT AVG(salary) FROM Employees e2 WHERE e1.Department = e2.department) -- 008 SELECT * FROM Departments d WHERE ( SELECT count (*) FROM Employees e WHERE e.Department = d.Department) > 2 -- 009 ALTER TABLE Departments ADD Location varchar(100) DEFAULT 'Houston' WITH VALUES; GO UPDATE Departments SET Location = 'New York' WHERE Department = 'Management' /* Evaluate performance differences between table joins and correlated subqueries based on provided data and query plans */ -- 010 SELECT * INTO Customers_copy FROM WideWorldImporters.sales.Customers SELECT * INTO orders_copy FROM WideWorldImporters.sales.orders -- 011 -- join faster SELECT c.CustomerName, o.lastorderdate, o.NumberOfOrders FROM (SELECT customerID, max(orderdate) AS LastOrderDate, count(*) AS NumberOfOrders FROM orders_copy GROUP BY CustomerID) o INNER JOIN Customers_copy c on c.CustomerID = o.customerId SELECT CustomerName ,( SELECT MAX(orderdate) FROM orders_copy o WHERE c.customerId = o.customerID ) AS LastOrderDate ,( SELECT COUNT(*) FROM orders_copy o WHERE c.customerId = o.customerID )AS NumberOfOrders FROM Customers_copy c -- 012 -- correlated subquery faster SELECT * FROM Customers_copy c LEFT OUTER JOIN orders_copy o on c.CustomerID = o.CustomerID WHERE o.CustomerID IS NULL SELECT * FROM Customers_copy c WHERE NOT EXISTS ( SELECT * FROM orders_copy o WHERE c.CustomerID = o.CustomerID) /* Distinguish between the use of CROSS APPLY and OUTER APPLY */ -- 013 SELECT * FROM Departments d CROSS APPLY ( SELECT * FROM Employees e WHERE e.Department = d.Department) table_alias SELECT * FROM Departments d INNER JOIN Employees e ON d.Department = e.Department -- 014 INSERT Departments VALUES ('Research', 'Eindhoven') SELECT * FROM Departments d OUTER APPLY ( SELECT * FROM Employees e WHERE e.Department = d.Department) table_alias SELECT * FROM Departments d LEFT OUTER JOIN Employees e ON d.Department = e.Department -- 015 CREATE FUNCTION dbo.fn_GetListOfEmployees(@Department AS varchar(100)) RETURNS TABLE AS RETURN ( SELECT FirstName + ' ' + LastName AS FullName, Salary FROM Employees e WHERE e.Department = @Department ) -- 016 SELECT * FROM dbo.fn_GetListOfEmployees('Engineering') -- 017 SELECT * FROM Departments d CROSS APPLY dbo.fn_GetListOfEmployees(d.Department) -- 018 SELECT session_id, DB_NAME(database_id) AS [database], start_time , open_transaction_count, [text] AS [Query] FROM sys.dm_exec_requests r CROSS APPLY sys.dm_exec_sql_text(r.plan_handle) s WHERE session_id > 50 -- Exclude system spids ORDER BY session_id; /* Query data by using table expressions */ --Identify basic components of table expressions SELECT o.* FROM (SELECT * FROM Sales.Orders) o -- common table expression WITH o AS ( SELECT * FROM Sales.Orders) SELECT * FROM o SELECT * FROM dbo.Employees e1 WHERE Salary > ( SELECT AVG(salary) FROM Employees e2 WHERE e1.Department = e2.department); -- readability example SELECT c.CustomerName, o.lastorderdate, o.NumberOfOrders FROM (SELECT customerID, max(orderdate) AS LastOrderDate, count(*) AS NumberOfOrders FROM orders_copy GROUP BY CustomerID) o INNER JOIN Customers_copy c on c.CustomerID = o.customerId; WITH o AS ( SELECT customerID, max(orderdate) AS LastOrderDate, count(*) AS NumberOfOrders FROM orders_copy GROUP BY CustomerID) SELECT c.CustomerName, o.lastorderdate, o.NumberOfOrders FROM o INNER JOIN Customers_copy c on c.CustomerID = o.customerId --Construct recursive table expressions to meet business requirements -- Recursive cte, top to bottom: ALTER TABLE Employees ADD ManagerID tinyint NULL; GO INSERT Employees (FirstName,LastName, Salary, Department, ManagerID) VALUES ('Harriet', 'Hughes', 1800.00,'Sales',7); INSERT Employees (FirstName,LastName, Salary, Department, ManagerID) VALUES ('Ronnie', 'Robertson', 1800.00,'Engineering',7); UPDATE Employees SET ManagerID = (SELECT EmployeeID FROM Employees WHERE FirstName = 'Harriet') WHERE Department = 'Sales' AND FirstName <> 'Harriet' UPDATE Employees SET ManagerID = (SELECT EmployeeID FROM Employees WHERE FirstName = 'Ronnie') WHERE Department = 'Engineering' AND FirstName <> 'Ronnie' ALTER TABLE Employees ADD CONSTRAINT PK_EmployeeID PRIMARY KEY (EmployeeID) ALTER TABLE Employees ADD CONSTRAINT FK_EmployeeID FOREIGN KEY (ManagerID) REFERENCES Employees(EmployeeID) GO WITH Employee_CTE AS ( SELECT EmployeeID, ManagerID, Firstname + ' ' + LastName AS Name, 0 as Level FROM Employees WHERE ManagerID IS NULL UNION ALL SELECT e1.EmployeeID, e1.ManagerID, Firstname + ' ' + LastName, e2.level + 1 FROM Employees e1 INNER JOIN Employee_CTE e2 ON e2.EmployeeID = e1.ManagerID ) SELECT Name, Level FROM Employee_CTE ORDER BY Level, Name -- Recursive cte, bottom to top: WITH Employee_CTE AS ( SELECT EmployeeID, ManagerID, Firstname + ' ' + LastName AS Name, 0 as Level FROM Employees WHERE EmployeeID NOT IN (SELECT ManagerID FROM Employees WHERE ManagerID IS NOT NULL) UNION ALL SELECT e1.EmployeeID, e1.ManagerID, Firstname + ' ' + LastName, e2.level + 1 FROM Employees e1 INNER JOIN Employee_CTE e2 ON e1.EmployeeID = e2.ManagerID ) SELECT DISTINCT Name, Level FROM Employee_CTE ORDER BY Level, Name -- Recursive CTE, final example WITH Employee_CTE AS ( SELECT EmployeeID, ManagerID, 0 as Level FROM Employees WHERE EmployeeID NOT IN (SELECT ManagerID FROM Employees WHERE ManagerID IS NOT NULL) UNION ALL SELECT e1.EmployeeID, e1.ManagerID, e2.level + 1 FROM Employees e1 INNER JOIN Employee_CTE e2 ON e1.EmployeeID = e2.ManagerID ) , Distinct_CTE AS ( SELECT DISTINCT EmployeeID, ManagerID, Level FROM Employee_CTE) SELECT e2.FirstName + ' ' + e2.LastName AS Name, e3.FirstName + ' ' + e3.LastName AS Manager, Level FROM Distinct_CTE e1 INNER JOIN Employees e2 ON e1.employeeID = e2.EmployeeID LEFT OUTER JOIN Employees e3 ON e1.ManagerID = e3.EmployeeID ORDER BY Level, Name --multiple CTEs WITH Employee_CTE AS ( SELECT EmployeeID, ManagerID, 0 as Level FROM Employees WHERE EmployeeID NOT IN ( SELECT ManagerID FROM Employees WHERE ManagerID IS NOT NULL) UNION ALL SELECT e1.EmployeeID, e1.ManagerID, e2.level + 1 FROM Employees e1 INNER JOIN Employee_CTE e2 ON e1.EmployeeID = e2.ManagerID ) , Distinct_CTE AS ( SELECT DISTINCT EmployeeID, ManagerID, Level FROM Employee_CTE) SELECT e2.FirstName + ' ' + e2.LastName AS Name , e3.FirstName + ' ' + e3.LastName AS Manager, Level FROM Distinct_CTE e1 INNER JOIN Employees e2 ON e1.employeeID = e2.EmployeeID LEFT OUTER JOIN Employees e3 ON e1.ManagerID = e3.EmployeeID ORDER BY Level, Name --Temporary table SELECT * INTO #tmp_Employees FROM Employees SELECT * FROM #tmp_Employees ALTER TABLE #tmp_Employees ADD Description varchar(100) NULL DROP TABLE #tmp_Employees SELECT * FROM tempdb.sys.objects WHERE name LIKE '#tmp_Employees%' --Table variables DECLARE @Employees TABLE ( [EmployeeID] [tinyint] NOT NULL, [FirstName] [varchar](100) NULL, [LastName] [varchar](50) NULL, [Address] [varchar](100) NULL, [Salary] [decimal](18, 2) NULL, [Department] [varchar](100) NULL, [Employee_Number] [int] NULL, [ManagerID] [tinyint] NULL) INSERT INTO @Employees SELECT * FROM Employees --Group and pivot data by using queries --Construct complex GROUP BY clauses using GROUPING SETS, and CUBE DROP TABLE IF EXISTS UFO_Sightings; GO CREATE TABLE UFO_Sightings ( CountryID tinyint , Country varchar(50) , State varchar(50) , City varchar(50) , UFO_Sightings int ); INSERT INTO UFO_Sightings VALUES (1, 'Germany', NULL, 'Berlin', 1) INSERT INTO UFO_Sightings VALUES (1, 'Germany', NULL, 'Frankfurt', 2) INSERT INTO UFO_Sightings VALUES (1, 'Germany', NULL, 'Frankfurt', 3) INSERT INTO UFO_Sightings VALUES (2, 'United States', 'Texas', 'Houston', 1) INSERT INTO UFO_Sightings VALUES (2, 'United States', 'Texas', 'Paris', 2) INSERT INTO UFO_Sightings VALUES (2, 'United States', 'Nevada', NULL, 300) INSERT INTO UFO_Sightings VALUES (3, 'France', NULL, 'Paris', 1); SELECT * FROM UFO_Sightings SELECT Country, SUM(UFO_Sightings) FROM UFO_Sightings GROUP BY Country SELECT SUM(UFO_Sightings) FROM UFO_Sightings SELECT SUM(UFO_Sightings) FROM UFO_Sightings GROUP BY () SELECT Country, City, SUM(UFO_Sightings) FROM UFO_Sightings GROUP BY Country, City ORDER BY Country, City; SELECT Country, SUM(UFO_Sightings) FROM UFO_Sightings WHERE City <> 'Paris' GROUP BY Country SELECT Country, SUM(UFO_Sightings) FROM UFO_Sightings WHERE ISNULL(City,'') <> 'Paris' GROUP BY Country SELECT CountryID, Country, SUM(UFO_Sightings) FROM UFO_Sightings GROUP BY Country SELECT Country, SUM(UFO_Sightings) AS TotalNumberOfSightings FROM UFO_Sightings GROUP BY Country HAVING SUM(UFO_Sightings) > 100; WITH ufo AS ( SELECT Country, SUM(UFO_Sightings) AS TotalNumberOfSightings FROM UFO_Sightings GROUP BY Country) SELECT * FROM ufo WHERE TotalNumberOfSightings > 100 INSERT INTO UFO_Sightings VALUES (4, 'Belgium', NULL, 'Brussels', NULL); SELECT Country, COUNT(UFO_Sightings) AS Count_1, COUNT(*) AS Count_2 FROM UFO_Sightings GROUP BY Country SELECT Country, State, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY Country, State --complex GROUP BY logic SELECT Country, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY Country, City ORDER BY Country, City SELECT Country, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY ROLLUP (Country, City); SELECT Country, NULL AS City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY Country UNION ALL SELECT Country, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY Country, City UNION ALL SELECT NULL, NULL, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY () GROUP BY Country, City WITH ROLLUP; SELECT Country, GROUPING(Country) AS Is_result_of_grouping_countries , State, GROUPING(State) AS Is_result_of_grouping_cities FROM UFO_Sightings GROUP BY Country, State WITH ROLLUP SELECT CASE WHEN GROUPING(Country) = 1 THEN 'Grand Total' WHEN GROUPING(State) = 1 THEN 'Total for ' + Country ELSE '' END AS Totals , Country , State ,SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY Country, State WITH ROLLUP SELECT Country, State, GROUPING_ID(Country, State ) FROM UFO_Sightings GROUP BY Country, State WITH ROLLUP ALTER TABLE UFO_Sightings ADD Continent varchar(100) NULL GO --required batch separator, otherwise query will fail on missing column UPDATE UFO_Sightings SET Continent = 'Europe' WHERE Country IN ('Germany', 'France', 'Belgium') UPDATE UFO_Sightings SET Continent = 'North America' WHERE Country IN ('United States') SELECT Continent , Country , State , GROUPING_ID(Continent, Country, State ) , GROUPING(Continent) * 4 + GROUPING(Country) * 2 + GROUPING(State) FROM UFO_Sightings GROUP BY Continent, Country, State WITH ROLLUP SELECT Country, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY CUBE (Country, City) ORDER BY 1, 2; -- CUBE dissected: A & NULL, NULL & B, A & B, NULL & NULL SELECT Country, NULL AS City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY (Country) UNION ALL SELECT NULL, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY ( City) UNION ALL SELECT Country, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY Country, City UNION ALL SELECT NULL, NULL, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings ORDER BY 1, 2 SELECT Continent , Country , City , SUM(UFO_Sightings) AS TotalUFO_Sightings , GROUPING_ID(Continent,Country, City) FROM UFO_Sightings GROUP BY CUBE (Continent, Country, City) ORDER BY 5; SELECT Country, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY GROUPING SETS ( Country, City) SELECT Country, NULL, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY Country UNION ALL SELECT NULL, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY City SELECT Country, City, SUM(UFO_Sightings) AS TotalUFO_Sightings FROM UFO_Sightings GROUP BY GROUPING SETS ( Country, City, ()) --Use windowing functions to group and rank the results of a query DROP TABLE IF EXISTS Runner_info CREATE TABLE Runner_info ( Runner varchar(50) ,Nickname varchar(50) ,Race varchar(50) ,Race_date date ,Distance decimal(8,3) ,Finish_time time) GO INSERT Runner_info VALUES ('Jack', 'The Flash', 'New York marathon', '2016-11-06', 42.195, '2:53:00') INSERT Runner_info VALUES ('Jack', 'The Flash', 'New York marathon', '2017-11-05', 42.195, '2:55:00') INSERT Runner_info VALUES ('Jack', 'The Flash', 'Berlin marathon', '2016-09-25', 42.195, '2:45:00') INSERT Runner_info VALUES ('Juan Gonzalez', 'Speedy', 'New York marathon', '2016-11-06', 42.195, '3:22:00') INSERT Runner_info VALUES ('Juan Gonzalez', 'Speedy', 'New York marathon', '2017-11-05', 42.195, '3:18:30') INSERT Runner_info VALUES ('Rudy', 'Roadrunner', 'New York marathon', '2016-11-06', 42.195, '4:01:00') INSERT Runner_info VALUES ('Rudy', 'Roadrunner', 'New York marathon', '2017-11-05', 42.195, '4:05:30') INSERT Runner_info VALUES ('Rudy', 'Roadrunner', 'Berlin marathon', '2016-09-25', 42.195, '3:59:59') INSERT Runner_info VALUES ('Rudy', 'Roadrunner', 'Berlin marathon', '2017-09-24', 42.195, '4:13:00') INSERT Runner_info VALUES ('Rudy', 'Roadrunner', 'Rotterdam half marathon', '2017-04-07', 21.1, '1:52') SELECT * FROM Runner_info SELECT * ,COUNT(*) OVER () AS Nr_of_races_total FROM Runner_info SELECT * ,COUNT(*) OVER () AS Nr_of_races_total ,COUNT(*) OVER (PARTITION BY Runner) AS Nr_of_races_per_runner FROM Runner_info SELECT * ,COUNT(*) OVER (PARTITION BY Runner) AS Nr_of_races_per_runner FROM Runner_info WHERE Distance = 42.195 SELECT Runner ,Race ,Race_date ,Finish_time ,MIN(Finish_time) OVER (PARTITION BY Runner, Race) AS Race_PR ,DATEDIFF(mi,MIN(Finish_time) OVER (PARTITION BY Runner, Race), Finish_time) AS Slower_than_PR FROM Runner_info OVER ( PARTITION BY column ORDER BY column ROWS BETWEEN … AND …) SELECT Runner, Race, Race_date, distance ,SUM(distance) OVER (PARTITION BY Runner ORDER BY Race_date ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS Cumulative_distance FROM Runner_info WHERE Runner = 'Rudy' ORDER BY Runner, Race_date SELECT Runner, Race, Race_date, distance ,AVG(distance) OVER (PARTITION BY Runner ORDER BY Race_date ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) AS Running_average FROM Runner_info WHERE Runner = 'Rudy' ORDER BY Runner, Race_date INSERT Runner_info VALUES ('Rudy', 'Roadrunner', 'Ran home', '2017-11-05', 10, '1:10') SELECT Runner, Race, Race_date, distance ,SUM(distance) OVER (PARTITION BY Runner ORDER BY Race_date ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS Cumulative_distance FROM Runner_info WHERE Runner = 'Rudy' ORDER BY Runner, Race_date SELECT Runner, Race, Race_date, distance ,SUM(distance) OVER (PARTITION BY Runner ORDER BY Race_date RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS Cumulative_distance FROM Runner_info WHERE Runner = 'Rudy' ORDER BY Runner, Race_date --Ranking window functions SELECT Runner, Race, Race_date, Finish_time ,ROW_NUMBER() OVER (ORDER BY Finish_time) AS rownumber ,RANK() OVER (ORDER BY Finish_time) AS rank ,DENSE_RANK() OVER (ORDER BY Finish_time) AS denserank ,NTILE(5) OVER (ORDER BY Finish_time) AS ntile FROM Runner_info WHERE Distance = 42.195 ORDER BY rownumber INSERT Runner_info VALUES ('Fred', 'The Shadow', 'New York marathon', '2016-11-06', 42.195, '2:53:00') --Analytic window functions SELECT FirstName, LastName, Department, Salary FROM dbo.Employees SELECT FirstName, LastName, Department, Salary ,LAG(Salary) OVER (ORDER BY Salary) as lag ,LEAD(Salary) OVER (ORDER BY Salary) as lead FROM Employees SELECT FirstName, LastName, Department, Salary ,LAG(Salary) OVER (ORDER BY Salary) as lag ,LEAD(Salary) OVER (ORDER BY Salary) as lead FROM Employees ORDER BY LastName SELECT FirstName, LastName, Department, Salary ,LAG(Salary, 2) OVER (ORDER BY Salary) as lag ,LEAD(Salary, 2) OVER (ORDER BY Salary) as lead FROM Employees SELECT FirstName, LastName, Department, Salary ,LAG(Salary, 2, 'not applicable') OVER (ORDER BY Salary) as lag ,LEAD(Salary, 2, 'not applicable') OVER (ORDER BY Salary) as lead FROM Employees SELECT FirstName, LastName, Department, Salary ,LAG(Salary) OVER (PARTITION BY Department ORDER BY Salary) as lag ,LEAD(Salary) OVER (PARTITION BY Department ORDER BY Salary) as lead FROM Employees ORDER BY Department SELECT FirstName, LastName, Department, Salary ,FIRST_VALUE(FirstName + ' ' + LastName) OVER ( PARTITION BY Department ORDER BY Salary) as Least_earning_employee ,LAST_VALUE(FirstName + ' ' + LastName) OVER ( PARTITION BY Department ORDER BY Salary RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) as Most_earning_employee FROM Employees ORDER BY Department, Salary SELECT FirstName, LastName, Department, Salary ,CUME_DIST() OVER (ORDER BY Salary) as cumulative_distance ,CUME_DIST() OVER (ORDER BY Salary) * COUNT(*) OVER () as equal_or_less FROM Employees ORDER BY Salary INSERT dbo.Employees (FirstName, LastName, Salary, Department) VALUES ('James', 'Peterson', 900, 'Engineering') SELECT FirstName, LastName, Department, Salary ,PERCENTILE_CONT(0.5) WITHIN GROUP (ORDER BY Salary) OVER () as median_salary ,PERCENTILE_DISC(0.5) WITHIN GROUP (ORDER BY Salary) OVER () as median_salary FROM Employees ORDER BY Salary SELECT FirstName, LastName, Department, Salary ,PERCENT_RANK() OVER (ORDER BY Salary) as fraction_lower_than_this ,CAST(PERCENT_RANK() OVER (ORDER BY Salary) * 100 AS dec(5,1)) as percentage_lower_than_this FROM Employees ORDER BY Salary --Construct PIVOT and UNPIVOT statements to return desired results based on supplied data SELECT CustomerName, si.StockItemName, sum(quantity) as quantity FROM sales.Customers c INNER JOIN sales.Orders o on c.CustomerID = o.CustomerID INNER JOIN sales.OrderLines ol on o.OrderID = ol.OrderID INNER JOIN Warehouse.StockItems si on ol.StockItemID = si.StockItemID WHERE c.CustomerID IN ( SELECT TOP 5 CustomerID FROM Sales.Orders GROUP BY CustomerID ORDER BY COUNT(*)) AND si.StockItemID IN ( SELECT TOP 5 StockItemID FROM Sales.Orderlines GROUP BY StockItemID ORDER BY COUNT(*)) GROUP BY CustomerName, si.StockItemName ORDER BY CustomerName, si.StockItemName --PIVOT and UNPIVOT WITH cte AS( SELECT CustomerName, si.StockItemName, quantity FROM sales.Customers c INNER JOIN sales.Orders o on c.CustomerID = o.CustomerID INNER JOIN sales.OrderLines ol on o.OrderID = ol.OrderID INNER JOIN Warehouse.StockItems si on ol.StockItemID = si.StockItemID WHERE si.StockItemID IN ( SELECT TOP 5 StockItemID FROM Sales.Orderlines GROUP BY StockItemID ORDER BY COUNT(*)) ) SELECT * FROM cte PIVOT (SUM(quantity) FOR CustomerName IN ([Anand Mudaliyar],[Jibek Juniskyzy] ,[Agrita Abele],[Kalyani Benjaree],[Jaroslav Fisar])) AS SalesQuantity USE TestDB GO DROP TABLE IF EXISTS Sales; GO CREATE TABLE Sales( Customer varchar(50) , Product varchar(50) , Quantity int) INSERT INTO Sales(Customer, Product, Quantity) VALUES('John','Apples',4) ,('John','Bananas',7) ,('John','Cantaloupe',1) ,('John','Apples',5) ,('John','Beer',6) ,('Bill','Cantaloupe',3) ,('Bill','Beer',24) ,('Diana','Apples',6) ,('Diana','Bananas',5) ,('Diana','Cantaloupe',2) SELECT * FROM Sales -- Pivot customers SELECT Product, Bill, John, Diana FROM Sales PIVOT (SUM(Quantity) FOR Customer IN (Bill, John, Diana)) AS some_alias ORDER BY Product -- Pivot product SELECT Customer, Apples, Bananas, Cantaloupe , Beer, [Magic mushrooms] FROM Sales PIVOT (SUM(Quantity) FOR Product IN (Apples, Bananas, Cantaloupe , Beer, [Magic mushrooms])) AS some_alias ORDER BY Customer -- adding a column ALTER TABLE Sales ADD CustomerID int NULL GO UPDATE Sales SET CustomerID = 1 WHERE Customer = 'Bill' UPDATE Sales SET CustomerID = 2 WHERE Customer = 'John' UPDATE Sales SET CustomerID = 3 WHERE Customer = 'Diana' SELECT Product, Bill, John, Diana FROM Sales PIVOT (SUM(Quantity) FOR Customer IN (Bill, John, Diana)) AS some_alias ORDER BY Product ALTER TABLE Sales DROP CustomerID SELECT Customer, Apples, Bananas, Cantaloupe , Beer, [Magic mushrooms] INTO Pivoted_sales_table FROM Sales PIVOT (SUM(Quantity) FOR Product IN (Apples, Bananas, Cantaloupe , Beer, [Magic mushrooms])) AS some_alias ORDER BY Customer SELECT * FROM Pivoted_sales_table SELECT Customer, Product, Quantity FROM Pivoted_sales_table UNPIVOT( Quantity FOR Product IN ( Apples, Bananas, Cantaloupe , Beer, [Magic mushrooms]) ) AS some_alias --Determine the impact of NULL values in PIVOT and UNPIVOT queries --Count(*) not allowed SELECT Product, Bill, John, Diana FROM Sales PIVOT (COUNT(Quantity) FOR Customer IN (Bill, John, Diana)) AS some_alias ORDER BY Product SELECT Customer, Apples, Bananas, Cantaloupe , Beer, [Magic mushrooms] FROM Sales PIVOT (MIN(Quantity), MAX(Quantity) FOR Product IN (Apples, Bananas, Cantaloupe , Beer, [Magic mushrooms])) AS some_alias ORDER BY Customer USE TestDB GO DROP TABLE IF EXISTS Sales; DROP TABLE IF EXISTS Pivoted_sales_table; --Query temporal data and non-relational data --Query historic data by using temporal tables USE WideWorldImporters GO SELECT CountryName, LatestRecordedPopulation FROM Application.Countries SELECT CountryName, LatestRecordedPopulation FROM Application.Countries FOR SYSTEM_TIME AS OF '2013-01-01 00:00:00.0000000' WHERE CountryName = 'Australia' SELECT CountryName, LatestRecordedPopulation, ValidFrom, ValidTo FROM Application.Countries FOR SYSTEM_TIME ALL WHERE CountryName = 'Australia' SELECT CountryName, LatestRecordedPopulation, ValidFrom, ValidTo FROM Application.Countries FOR SYSTEM_TIME FROM '2013-07-01 16:00:00.0000000' TO '2015-07-01 16:00:00.0000000' WHERE CountryName = 'Australia' SELECT CountryName, LatestRecordedPopulation, ValidFrom, ValidTo FROM Application.Countries FOR SYSTEM_TIME BETWEEN '2013-07-01 16:00:00.0000000' AND '2015-07-01 16:00:00.0000000' WHERE CountryName = 'Australia' DECLARE @now datetime2 = SYSDATETIME() SELECT CountryName, LatestRecordedPopulation, ValidFrom, ValidTo FROM Application.Countries FOR SYSTEM_TIME CONTAINED IN ('2013-07-01 15:00:00.0000000', @now) WHERE CountryName = 'Australia' SELECT CountryName, LatestRecordedPopulation, ValidFrom, ValidTo FROM Application.Countries_archive WHERE CountryName = 'Australia' UNION ALL SELECT CountryName, LatestRecordedPopulation, ValidFrom, ValidTo FROM Application.Countries WHERE CountryName = 'Australia' USE TestDB GO IF EXISTS ( SELECT * FROM sys.tables WHERE name = 'Countries' AND temporal_type_desc = 'SYSTEM_VERSIONED_TEMPORAL_TABLE') BEGIN ALTER TABLE Countries SET ( SYSTEM_VERSIONING = OFF) END GO DROP TABLE IF EXISTS Countries_archive DROP TABLE IF EXISTS Countries GO CREATE TABLE Countries ( CountryID int IDENTITY PRIMARY KEY ,CountryName varchar(50) ,Population int ,ValidFrom datetime2 GENERATED ALWAYS AS ROW START HIDDEN ,ValidTo datetime2 GENERATED ALWAYS AS ROW END HIDDEN ,PERIOD FOR SYSTEM_TIME (ValidFrom,ValidTo)) WITH(SYSTEM_VERSIONING = ON (HISTORY_TABLE = dbo.Countries_archive)) GO INSERT Countries (CountryName, Population) VALUES ('Neverland', 100) UPDATE Countries SET Population = 101 WHERE CountryName = 'Neverland' SELECT *, ValidFrom, ValidTo FROM Countries FOR SYSTEM_TIME ALL ORDER BY ValidFrom BEGIN TRAN UPDATE Countries SET Population = 102 WHERE CountryName = 'Neverland' WAITFOR DELAY '00:00:10' UPDATE Countries SET Population = 103 WHERE CountryName = 'Neverland' COMMIT TRAN SELECT *, ValidFrom, ValidTo FROM Countries FOR SYSTEM_TIME ALL ORDER BY ValidFrom SELECT * FROM countries_archive DECLARE @local_time datetime2 ,@utc_time datetime2 SET @local_time = '2018-07-04 13:40:00' SET @utc_time = DATEADD(second, DATEDIFF(second, SYSDATETIME(), SYSUTCDATETIME()), @local_time) SELECT * FROM Countries FOR SYSTEM_TIME AS OF @utc_time DELETE FROM Countries_archive WHERE ValidTo <DATEADD(yy, -7, SYSUTCDATETIME()) ALTER TABLE Countries ADD Description varchar(100) NULL GO UPDATE Countries SET Description = 'Not an actual country' WHERE CountryName = 'Neverland' GO ALTER TABLE Countries DROP COLUMN Description USE TestDB GO IF EXISTS ( SELECT * FROM sys.tables WHERE name = 'Countries' AND temporal_type_desc = 'SYSTEM_VERSIONED_TEMPORAL_TABLE') BEGIN ALTER TABLE Countries SET ( SYSTEM_VERSIONING = OFF) END GO DROP TABLE IF EXISTS Countries_archive DROP TABLE IF EXISTS Countries GO CREATE TABLE Countries ( CountryID int IDENTITY PRIMARY KEY NOT NULL ,CountryName varchar(50) ,Population int) GO INSERT Countries (CountryName, Population) VALUES ('Neverland', 103) CREATE TABLE Countries_archive ( CountryID int NOT NULL --no identity or primary key ,CountryName varchar(50) ,Population int) GO ALTER TABLE Countries_archive ADD ValidFrom datetime2 NOT NULL ALTER TABLE Countries_archive ADD ValidTo datetime2 NOT NULL GO INSERT Countries_archive (CountryID, CountryName, Population, ValidFrom,ValidTo) VALUES (1, 'Neverland', 100, '2011-01-01', '2012-01-01') ALTER TABLE Countries ADD ValidFrom datetime2 NULL ALTER TABLE Countries ADD ValidTo datetime2 NULL GO UPDATE Countries SET ValidFrom = '2012-01-01' UPDATE Countries SET ValidTo = '9999-12-31 23:59:59.9999999' GO ALTER TABLE Countries ALTER COLUMN ValidFrom datetime2 NOT NULL ALTER TABLE Countries ALTER COLUMN ValidTo datetime2 NOT NULL GO ALTER TABLE Countries ADD PERIOD FOR SYSTEM_TIME (ValidFrom,ValidTo) ALTER TABLE Countries SET (SYSTEM_VERSIONING = ON (HISTORY_TABLE = dbo.Countries_archive)) SELECT [2012].population - [2011].population AS 'population growth' FROM Countries FOR SYSTEM_TIME AS OF '2011-01-01' AS [2011] INNER JOIN Countries FOR SYSTEM_TIME AS OF '2012-01-01' AS [2012] ON [2011].CountryID = [2012].CountryID --Query and output JSON data CREATE TABLE [dbo].[Employees]( [EmployeeID] [tinyint] IDENTITY(1,1) NOT NULL, [FirstName] [varchar](100) NULL, [LastName] [varchar](50) NULL, [Address] [varchar](100) NULL, [Employee_Number] [int] NULL ) INSERT dbo.Employees (FirstName, LastName, Address) VALUES ('Bob', 'Jackson', 'Under the bridge') ,('Bo', 'Didley', 'Home of mr. Bo Didley') DECLARE @json NVARCHAR(MAX) SET @json = '{"FirstName":"Bob"}' SELECT ISJSON(@json) AS 'IsValidJSON?' SELECT FirstName, lastname, address FROM employees WHERE EmployeeID = 1 FOR JSON AUTO --Format query output as JSON SELECT FirstName, lastname, address FROM employees WHERE EmployeeID in (1,2) FOR JSON AUTO SELECT FirstName, lastname, address FROM employees WHERE EmployeeID in (1,2) FOR JSON PATH SELECT FirstName, lastname, address FROM employees WHERE EmployeeID in (1,2) FOR JSON PATH, ROOT ('Employees') SELECT FirstName, lastname, address FROM employees WHERE EmployeeID in (1,2) FOR JSON PATH, WITHOUT_ARRAY_WRAPPER UPDATE Employees SET Employee_Number = employeeID WHERE EmployeeID = 1 SELECT FirstName, lastname, address, Employee_Number FROM employees WHERE EmployeeID in (1,2) FOR JSON PATH, INCLUDE_NULL_VALUES SELECT FirstName AS 'Name.FirstName' , lastname AS 'Name.LastName' , address FROM employees WHERE EmployeeID in (1,2) FOR JSON PATH --Extract data from JSON DECLARE @json NVARCHAR(MAX) SET @json = '{ "A null value":null ,"A text string":"string" ,"A number":2 ,"A boolean (true or false)":true ,"A boolean (true or false)":false ,"An array":[1,2,3] ,"An object": {"key1":"value1", "key2":"value2"} }' SELECT * FROM OPENJSON(@json) SELECT [key], value FROM OPENJSON(@json) WHERE type <> 0 SELECT [key], value FROM OPENJSON(@json,'$."An object"') SELECT [key], value FROM OPENJSON(@json,'$."An array"') SELECT [key], value FROM OPENJSON(@json,'lax $."n array"') SELECT [key], value FROM OPENJSON(@json,'strict $."n array"') SELECT * FROM OPENJSON(@json) WITH ( NameOfTheColumn bigint '$."A number"' ,NameOfTheOtherColumn varchar(100) '$."A text string"' ) SELECT * FROM OPENJSON(@json) WITH ( NameOfTheColumn bigint '$."A number"' ,NameOfTheOtherColumn varchar(100) '$."A text string"' ,JSONColumn nvarchar(max) '$."An object"' AS JSON ,ObjectValue varchar(100) '$."An object".key1' ) SELECT JSON_VALUE(@json, '$."A number"') SELECT JSON_QUERY(@json, '$."An object"') SELECT JSON_QUERY(@json, '$."A number"') SELECT JSON_VALUE(@json, '$."An object"') SELECT JSON_MODIFY(@json,'$."A number"', 17) SELECT JSON_VALUE(@json, '$.Employees[1].address') --Query and output XML data DECLARE @xml XML SET @XML = '<FirstName>Bob</Firstname>' SELECT @xml SELECT TRY_CAST('<FirstName>Bob</Firstname>' as XML) SELECT EmployeeID as '@Id' ,FirstName ,LastName FROM Employees WHERE EmployeeID in (1,2) FOR XML PATH ('Employee') --Format query output as XML SELECT EmployeeID ,FirstName ,LastName FROM Employees WHERE EmployeeID in (1,2) FOR XML RAW SELECT EmployeeID ,FirstName ,LastName FROM Employees WHERE EmployeeID in (1,2) FOR XML RAW ('GiveThisElementAnotherName') SELECT EmployeeID ,FirstName ,LastName FROM Employees WHERE EmployeeID in (1,2) FOR XML RAW , ELEMENTS SELECT EmployeeID ,FirstName ,LastName ,Employee_Number FROM Employees WHERE EmployeeID in (1,2) FOR XML RAW SELECT EmployeeID ,FirstName ,LastName ,Employee_Number FROM Employees WHERE EmployeeID in (1,2) FOR XML RAW, ELEMENTS XSINIL SELECT EmployeeID ,FirstName ,LastName FROM Employees WHERE EmployeeID in (1,2) FOR XML RAW, ROOT ('Employees') SELECT c.Customername, o.orderid, OrderDate FROM sales.Orders o INNER JOIN sales.Customers c on c.CustomerID = o.CustomerID WHERE c.customerId in (832, 803) AND YEAR(OrderDate)=2013 AND MONTH(OrderDate)=1 --ORDER BY OrderDate FOR XML AUTO SELECT EmployeeID as '@Id' ,FirstName ,LastName FROM Employees WHERE EmployeeID in (1,2) FOR XML PATH ('Employee') --outer query SELECT c.CustomerID AS '@id' ,c.Customername --subquery will be inserted here FROM sales.customers c WHERE c.customerId in (832, 803) ORDER BY c.CustomerName FOR XML PATH ('Customers'), ELEMENTS, ROOT ('CustomerOrders') --subquery SELECT o.orderid AS '@OrderID' ,o.OrderDate FROM sales.customers c2 INNER JOIN sales.orders o on c2.CustomerID = o.CustomerID WHERE c.customerID = c2.customerID AND YEAR(OrderDate)=2013 AND MONTH(OrderDate)=1 FOR XML PATH('Orders'), ROOT('CustomerOrderId'),TYPE --full query SELECT c.CustomerID AS '@id' ,c.Customername ,(SELECT o.orderid AS '@OrderID' ,o.OrderDate FROM sales.customers c2 INNER JOIN sales.orders o on c2.CustomerID = o.CustomerID WHERE c.customerID = c2.customerID AND YEAR(OrderDate)=2013 AND MONTH(OrderDate)=1 FOR XML PATH('Orders'), ROOT('CustomerOrderId'),TYPE) FROM sales.customers c WHERE c.customerId in (832, 803) ORDER BY c.CustomerName FOR XML PATH ('Customers'), ELEMENTS, ROOT ('CustomerOrders') SELECT ol.orderlineId as '@OrderLineID' ,ol.Description ,ol.Quantity FROM sales.orderlines ol inner join sales.orders o2 on ol.OrderID = o2.OrderID inner join sales.customers c3 on c3.CustomerID = o.CustomerID WHERE o2.OrderID = o.orderid FOR XML PATH ('OrderLines'), TYPE DECLARE @xml varchar(1000) DECLARE @xml_document_handle int SET @xml = ' <CustomerOrders> <Customers id="832"> <Customername>Aakriti Byrraju</Customername> </Customers> <Customers id="803"> <Customername>Bala Dixit</Customername> </Customers> </CustomerOrders> ' -- Step 1 EXEC sp_xml_preparedocument @xml_document_handle OUTPUT, @xml; --Step 2 SELECT * FROM OPENXML (@xml_document_handle, '/CustomerOrders/Customers',11) WITH ( id int, Customername varchar(200)); --Step 3 EXEC sp_xml_removedocument @xml_document_handle --XML output of customers, orders and order lines SELECT c.CustomerID AS '@id' ,c.Customername , (SELECT o.orderid AS '@OrderID' ,o.OrderDate ,(SELECT ol.orderlineId as '@OrderLineID' ,ol.Description ,ol.Quantity FROM sales.orderlines ol inner join sales.orders o2 on ol.OrderID = o2.OrderID inner join sales.customers c3 on c3.CustomerID = o.CustomerID WHERE o2.OrderID = o.orderid for XML PATH ('OrderLines'), TYPE ) FROM sales.customers c2 INNER JOIN sales.orders o on c2.CustomerID = o.CustomerID WHERE c.customerID = c2.customerID AND YEAR(OrderDate)=2013 AND MONTH(OrderDate)=1 FOR XML PATH('Orders'), ROOT('CustomerOrderId'),TYPE) FROM sales.customers c WHERE c.customerId in (832, 803) ORDER BY c.CustomerName FOR XML PATH ('Customers'), ELEMENTS, ROOT ('CustomerOrders') DECLARE @xml varchar(max) DECLARE @xml_document_handle int SET @xml = ' <CustomerOrders> <Customers id="832"> <Customername>Aakriti Byrraju</Customername> <CustomerOrderId> <Orders OrderID="1"> <OrderDate>2013-01-02</OrderDate> <OrderLines OrderLineID="2"> <Description>Ride on toy sedan car (Black) 1/12 scale</Description> <Quantity>10</Quantity> </OrderLines> </Orders> <Orders OrderID="45"> <OrderDate>2013-01-01</OrderDate> <OrderLines OrderLineID="1"> <Description>32 mm Double sided bubble wrap 50m</Description> <Quantity>50</Quantity> </OrderLines> </Orders> </CustomerOrderId> </Customers> <Customers id="803"> <Customername>Bala Dixit</Customername> <CustomerOrderId> <Orders OrderID="2"> <OrderDate>2013-01-01</OrderDate> <OrderLines OrderLineID="3"> <Description>Developer joke mug - old C developers never die (White)</Description> <Quantity>9</Quantity> </OrderLines> <OrderLines OrderLineID="6"> <Description>USB food flash drive - chocolate bar</Description> <Quantity>9</Quantity> </OrderLines> </Orders> </CustomerOrderId> </Customers> </CustomerOrders> ' -- Step 1 EXEC sp_xml_preparedocument @xml_document_handle OUTPUT, @xml; --Step 2 SELECT * FROM OPENXML (@xml_document_handle, '/CustomerOrders/Customers/CustomerOrderId/Orders/OrderLines',11) WITH ( id int '../../../@id', Customername varchar(1000) '../../../Customername', OrderDate date '../OrderDate', OrderID int '../@OrderID', Description varchar(1000)); --Step 3 EXEC sp_xml_removedocument @xml_document_handle --XQuery SELECT @xml.query('/CustomerOrders/Customers/CustomerOrderId/Orders/OrderLines') SELECT @xml.query('(/CustomerOrders/Customers/CustomerOrderId/Orders/OrderLines)[2]') SELECT @xml.query('(/CustomerOrders/Customers[2]/CustomerOrderId/Orders/OrderLines)[2]') SELECT @xml.query('(/CustomerOrders/Customers[@id=803]/CustomerOrderId/Orders/OrderLines)') SELECT @xml.query('(/CustomerOrders/Customers[Customername="Bala Dixit"]/CustomerOrderId/Orders/OrderLines)') --FLWOR SELECT @xml.query(' for $Orders in /CustomerOrders/Customers/CustomerOrderId/Orders return ($Orders) ') SELECT @xml.query(' for $Orders in /CustomerOrders/Customers/CustomerOrderId/Orders return string($Orders) ') SELECT @xml.query(' for $Orders in /CustomerOrders/Customers/CustomerOrderId/Orders let $Quantity :=$Orders/OrderLines/Quantity where $Quantity > 20 return ($Orders) ') SELECT @xml.query(' for $Orders in /CustomerOrders/Customers/CustomerOrderId/Orders order by $Orders/@OrderID return $Orders ') --XQuery value SELECT @xml.value('(/CustomerOrders/Customers[2]/CustomerOrderId/Orders/OrderLines)[1]', 'varchar(1000)') SELECT @xml.value('(/CustomerOrders/Customers[2]/CustomerOrderId/Orders/OrderLines)[1]', 'int') --XQuery exist SELECT @xml.exist('(/CustomerOrders/Customers/CustomerOrderId/Orders/OrderLines)[5]') SELECT @xml.exist('(/CustomerOrders/Customers[@id] = 832)') --XQuery nodes SELECT XML_table.value('../../../@id', N'int') as customerid ,XML_table.value('../../../Customername[1]', 'varchar(100)') as customername ,XML_table.value('../@OrderID', 'varchar(100)') as Orderid ,XML_table.value('@OrderLineID', 'varchar(100)') as OrderLineid ,XML_table.value('Quantity[1]', 'varchar(100)') as quantity ,XML_table.value('Description[1]', 'varchar(100)') as description FROM @xml.nodes('/CustomerOrders/Customers/CustomerOrderId/Orders/OrderLines') as t(XML_table) ORDER BY customerid desc SELECT XML_table.value('../../@id', N'int') as customerid ,XML_table.value('@OrderID', N'int') as orderID ,XML_table.query('.') as orderdetails FROM @xml.nodes('/CustomerOrders/Customers/CustomerOrderId/Orders') as t(XML_table) --XQuery modify DECLARE @xml XML SET @xml = ' <Employees> <Employee Id="1"> <FirstName>Bob</FirstName> <LastName>Jackson</LastName> </Employee> <Employee Id="2"> <FirstName>Bo</FirstName> <LastName>Didley</LastName> </Employee> </Employees> ' SET @xml.modify(' insert attribute SSID {"idontknow"} into (/Employees/Employee)[2] ') SET @xml.modify(' insert <Employee Id="3"><FirstName>Jeff</FirstName><LastName>Williams</LastName></Employee> after (/Employees/Employee)[2] ') SET @xml.modify(' insert <Employee Id="3"><FirstName>Jeff</FirstName><LastName>Williams</LastName></Employee> into (/Employees)[1] ') --XQuery delete SET @xml.modify(' delete /Employees/Employee[2]/@SSID ') SET @xml.modify(' delete /Employees/Employee[2]/Address ') If the element or attribute isn’t present, no error will be returned. SET @xml.modify(' replace value of (/Employees/Employee[2]/@SSID)[1] with "001-002-003" ') SET @xml.modify(' replace value of (/Employees/Employee[2]/Address/text())[1] with "Beverly Hills" ') |
Posted in Code samples, MCSA SQL 2016 70-761
Leave a comment