-
Recent Posts
Archives
Categories
Monthly Archives: October 2019
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