├── LICENSE.txt
├── Appendix_0B.pdf
├── 9781484219720.jpg
├── Code
├── Appendix A.sql
├── Appendix B.sql
├── Chapter 08.sql
├── Chapter 09.sql
├── Chapter 12.sql
├── Chapter 14
│ ├── HealthcareLoad
│ │ ├── HealthcareLoad
│ │ │ ├── Project.params
│ │ │ ├── obj
│ │ │ │ └── Development
│ │ │ │ │ ├── Project.params
│ │ │ │ │ ├── Package.dtsx
│ │ │ │ │ ├── BuildLog.xml
│ │ │ │ │ └── LoadDimProcedure.dtsx
│ │ │ ├── bin
│ │ │ │ └── Development
│ │ │ │ │ └── HealthcareLoad.ispac
│ │ │ ├── HealthcareLoad.dtproj.user
│ │ │ ├── HealthcareLoad.database
│ │ │ └── LoadDimProcedure.dtsx
│ │ ├── .vs
│ │ │ └── HealthcareLoad
│ │ │ │ └── v14
│ │ │ │ └── .suo
│ │ └── HealthcareLoad.sln
│ ├── Summary DDL and Load and Query and Index Script.sql
│ ├── Analytical Dimensional Query and Index Script.sql
│ ├── Operational DDL and Load and Query and Index Script.sql
│ └── Analytical Dimensional DDL and Load Script.sql
├── Chapter 06-Database Create Objects.sql
├── Chapter 06-Database Create Objects-In Mem.sql
├── Chapter 12 Suppliment - Numbers Table Stupid Math Tricks.sql
├── Chapter 06-CreateOnPrem DB.sql
├── Chapter 06-TestScriptOnly.sql
├── Chapter 10.sql
├── Chapter 13.sql
├── Chapter 11.sql
└── Chapter 07.sql
├── README.md
└── contributing.md
/LICENSE.txt:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/LICENSE.txt
--------------------------------------------------------------------------------
/Appendix_0B.pdf:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Appendix_0B.pdf
--------------------------------------------------------------------------------
/9781484219720.jpg:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/9781484219720.jpg
--------------------------------------------------------------------------------
/Code/Appendix A.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Appendix A.sql
--------------------------------------------------------------------------------
/Code/Appendix B.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Appendix B.sql
--------------------------------------------------------------------------------
/Code/Chapter 08.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 08.sql
--------------------------------------------------------------------------------
/Code/Chapter 09.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 09.sql
--------------------------------------------------------------------------------
/Code/Chapter 12.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 12.sql
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/Project.params:
--------------------------------------------------------------------------------
1 |
2 |
--------------------------------------------------------------------------------
/Code/Chapter 06-Database Create Objects.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 06-Database Create Objects.sql
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/obj/Development/Project.params:
--------------------------------------------------------------------------------
1 |
2 |
--------------------------------------------------------------------------------
/Code/Chapter 06-Database Create Objects-In Mem.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 06-Database Create Objects-In Mem.sql
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/.vs/HealthcareLoad/v14/.suo:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 14/HealthcareLoad/.vs/HealthcareLoad/v14/.suo
--------------------------------------------------------------------------------
/Code/Chapter 12 Suppliment - Numbers Table Stupid Math Tricks.sql:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 12 Suppliment - Numbers Table Stupid Math Tricks.sql
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/bin/Development/HealthcareLoad.ispac:
--------------------------------------------------------------------------------
https://raw.githubusercontent.com/Apress/pro-sql-server-rel-db-design-impl/HEAD/Code/Chapter 14/HealthcareLoad/HealthcareLoad/bin/Development/HealthcareLoad.ispac
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # Apress Source Code
2 |
3 | This repository accompanies [*Pro SQL Server Relational Database Design and Implementation*](http://www.apress.com/9781484219720) by Louis Davidson and Jessica Moss (Apress, 2016).
4 |
5 | 
6 |
7 | Download the files as a zip using the green button, or clone the repository to your machine using Git.
8 |
9 | ## Releases
10 |
11 | Release v1.0 corresponds to the code in the published book, without corrections or updates.
12 |
13 | ## Contributions
14 |
15 | See the file Contributing.md for more information on how you can contribute to this repository.
16 |
--------------------------------------------------------------------------------
/contributing.md:
--------------------------------------------------------------------------------
1 | # Contributing to Apress Source Code
2 |
3 | Copyright for Apress source code belongs to the author(s). However, under fair use you are encouraged to fork and contribute minor corrections and updates for the benefit of the author(s) and other readers.
4 |
5 | ## How to Contribute
6 |
7 | 1. Make sure you have a GitHub account.
8 | 2. Fork the repository for the relevant book.
9 | 3. Create a new branch on which to make your change, e.g.
10 | `git checkout -b my_code_contribution`
11 | 4. Commit your change. Include a commit message describing the correction. Please note that if your commit message is not clear, the correction will not be accepted.
12 | 5. Submit a pull request.
13 |
14 | Thank you for your contribution!
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/obj/Development/Package.dtsx:
--------------------------------------------------------------------------------
1 |
2 |
15 | 8
17 |
18 |
19 |
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad.sln:
--------------------------------------------------------------------------------
1 |
2 | Microsoft Visual Studio Solution File, Format Version 12.00
3 | # Visual Studio 14
4 | VisualStudioVersion = 14.0.23107.0
5 | MinimumVisualStudioVersion = 10.0.40219.1
6 | Project("{159641D6-6404-4A2A-AE62-294DE0FE8301}") = "HealthcareLoad", "HealthcareLoad\HealthcareLoad.dtproj", "{D18AC4B8-132B-4F94-980E-DDB7320E0C25}"
7 | EndProject
8 | Global
9 | GlobalSection(SolutionConfigurationPlatforms) = preSolution
10 | Development|Default = Development|Default
11 | EndGlobalSection
12 | GlobalSection(ProjectConfigurationPlatforms) = postSolution
13 | {D18AC4B8-132B-4F94-980E-DDB7320E0C25}.Development|Default.ActiveCfg = Development
14 | {D18AC4B8-132B-4F94-980E-DDB7320E0C25}.Development|Default.Build.0 = Development
15 | EndGlobalSection
16 | GlobalSection(SolutionProperties) = preSolution
17 | HideSolutionNode = FALSE
18 | EndGlobalSection
19 | EndGlobal
20 |
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/HealthcareLoad.dtproj.user:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 |
5 | Development
6 |
7 | true
8 |
9 |
10 | false
11 | true
12 |
13 |
14 | LastModifiedTime
15 | LastModifiedTime
16 | 2016-07-30T18:31:41.8469015Z
17 |
18 |
19 |
20 |
21 |
22 |
--------------------------------------------------------------------------------
/Code/Chapter 06-CreateOnPrem DB.sql:
--------------------------------------------------------------------------------
1 | :setvar OnPremRebuilddB Yes
2 | use master
3 |
4 | if '$(OnPremRebuildDb)' = 'Yes'
5 | --drop db if you are recreating it, dropping all connections to existing database.
6 | if exists (select * from sys.databases where name = 'ConferenceMessaging')
7 | exec ('
8 | alter database ConferenceMessaging
9 | set single_user with rollback immediate;
10 |
11 | drop database ConferenceMessaging;')
12 | go
13 | if not exists (select * from sys.databases where name = 'ConferenceMessaging')
14 | CREATE DATABASE ConferenceMessaging
15 | -- ON
16 | -- PRIMARY ( NAME = N'ConferenceMessaging', FILENAME = N'C:\SQL\DATA\ConferenceMessaging.mdf' ,
17 | -- SIZE = 1024MB , MAXSIZE = 1024MB)
18 | --LOG ON
19 | -- ( NAME = N'ConferenceMessaging_log', FILENAME = N'C:\SQL\LOG\ConferenceMessaging_log.ldf' ,
20 | -- SIZE = 100MB , MAXSIZE = 2048GB , FILEGROWTH = 100MB);
21 | GO
22 | use ConferenceMessaging
23 |
24 | select *
25 | from sys.master_files
26 | where database_id = db_id()
27 |
28 | ALTER AUTHORIZATION ON Database::ConferenceMessaging to SA;
29 |
30 |
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/obj/Development/BuildLog.xml:
--------------------------------------------------------------------------------
1 |
2 |
3 |
4 | HealthcareLoad
5 | 2016-07-31T15:19:04.7574236Z
6 | EncryptSensitiveWithUserKey
7 |
8 |
9 |
10 | Package.dtsx
11 | 2016-07-30T18:15:46.1346193Z
12 | EncryptSensitiveWithUserKey
13 |
14 |
15 | LoadDimProcedure.dtsx
16 | 2016-07-31T15:14:15.9646062Z
17 | EncryptSensitiveWithUserKey
18 |
19 |
20 | LoadDimDiagnosis.dtsx
21 | 2016-07-31T15:19:04.7415143Z
22 | EncryptSensitiveWithUserKey
23 |
24 |
25 |
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/HealthcareLoad.database:
--------------------------------------------------------------------------------
1 |
2 | HealthcareLoad
3 | HealthcareLoad
4 | 0001-01-01T00:00:00Z
5 | 0001-01-01T00:00:00Z
6 | 0001-01-01T00:00:00Z
7 | Unprocessed
8 | 0001-01-01T00:00:00Z
9 |
10 | Default
11 | Unchanged
12 |
13 |
--------------------------------------------------------------------------------
/Code/Chapter 14/Summary DDL and Load and Query and Index Script.sql:
--------------------------------------------------------------------------------
1 | USE [Chapter14];
2 | GO
3 |
4 | -- Create schema for summary tables
5 | CREATE SCHEMA [sum];
6 | GO
7 |
8 | -- Create Daily Claims table
9 | CREATE TABLE [sum].DailyClaims (
10 | ClaimDate DATE NOT NULL,
11 | AdjudicationType VARCHAR(6) NOT NULL,
12 | ClaimCount INTEGER NOT NULL,
13 | ClaimAmount DECIMAL(10,2) NOT NULL
14 | );
15 | GO
16 |
17 | -- Add sample data for summary tables
18 | DECLARE @i INT;
19 | SET @i = 0;
20 |
21 | WHILE @i < 1000
22 | BEGIN
23 | INSERT INTO sum.DailyClaims
24 | (
25 | ClaimDate, AdjudicationType, ClaimCount, ClaimAmount
26 | )
27 | SELECT
28 | CONVERT(CHAR(8), DATEADD(dd, RAND() * -100, getdate()), 112),
29 | CASE CEILING(2 * RAND())
30 | WHEN 1 THEN 'AUTO'
31 | ELSE 'MANUAL'
32 | END,
33 | 1,
34 | RAND() * 100000;
35 | SET @i = @i + 1;
36 | END;
37 | GO
38 |
39 | -- Create Monthly Claims table
40 | CREATE TABLE [sum].MonthlyClaims (
41 | ClaimMonth INTEGER NOT NULL,
42 | ClaimYear INTEGER NOT NULL,
43 | AdjudicationType VARCHAR(6) NOT NULL,
44 | ClaimCount INTEGER NOT NULL,
45 | ClaimAmount DECIMAL(10,2) NOT NULL
46 | );
47 | GO
48 |
49 | -- Create Yearly Claims table
50 | CREATE TABLE [sum].YearlyClaims (
51 | ClaimYear INTEGER NOT NULL,
52 | AdjudicationType VARCHAR(6) NOT NULL,
53 | ClaimCount INTEGER NOT NULL,
54 | ClaimAmount DECIMAL(10,2) NOT NULL
55 | );
56 | GO
57 |
58 | -- Insert summarized data
59 | INSERT INTO sum.MonthlyClaims
60 | SELECT MONTH(ClaimDate), YEAR(ClaimDate), AdjudicationType,
61 | SUM(ClaimCount), SUM(ClaimAmount)
62 | FROM sum.DailyClaims
63 | GROUP BY MONTH(ClaimDate), YEAR(ClaimDate), AdjudicationType;
64 | GO
65 |
66 | INSERT INTO sum.YearlyClaims
67 | SELECT YEAR(ClaimDate), AdjudicationType, SUM(ClaimCount), SUM(ClaimAmount)
68 | FROM sum.DailyClaims
69 | GROUP BY YEAR(ClaimDate), AdjudicationType;
70 | GO
71 |
72 | -- Queries and Indexes
73 | SELECT ClaimDate, AdjudicationType, ClaimCount, ClaimAmount
74 | FROM sum.DailyClaims;
75 |
76 | SELECT ClaimMonth, ClaimYear, AdjudicationType, ClaimCount, ClaimAmount
77 | FROM sum.MonthlyClaims;
78 |
79 | SELECT ClaimYear, AdjudicationType, ClaimCount, ClaimAmount
80 | FROM sum.YearlyClaims;
81 |
82 | SELECT ClaimDate, AdjudicationType, ClaimCount, ClaimAmount
83 | FROM sum.DailyClaims
84 | WHERE ClaimDate BETWEEN DATEADD(MONTH, -3, getdate()) and getdate()
85 | ORDER BY ClaimDate;
86 |
87 | SELECT ClaimMonth, ClaimYear, [AUTO], [MANUAL]
88 | FROM
89 | (SELECT ClaimMonth, ClaimYear, AdjudicationType, ClaimAmount
90 | FROM sum.MonthlyClaims) AS Claims
91 | PIVOT
92 | (
93 | SUM(ClaimAmount)
94 | FOR AdjudicationType IN ([AUTO], [MANUAL])
95 | ) AS PivotedClaims;
96 |
97 | SELECT SUM(ClaimCount)
98 | FROM sum.DailyClaims
99 | WHERE ClaimDate = '07/10/2016';
100 |
101 | CREATE NONCLUSTERED INDEX NonClusteredIndex ON sum.DailyClaims
102 | (
103 | ClaimDate ASC,
104 | ClaimCount
105 | );
106 | GO
107 |
--------------------------------------------------------------------------------
/Code/Chapter 14/Analytical Dimensional Query and Index Script.sql:
--------------------------------------------------------------------------------
1 | USE [Chapter14];
2 | GO
3 |
4 | SELECT count(fcp.ClaimID) AS DeniedClaimCount
5 | FROM fact.ClaimPayment fcp
6 | INNER JOIN dim.AdjudicationType da ON fcp.AdjudicationTypeKey=da.AdjudicationTypeKey
7 | INNER JOIN dim.Date dd ON fcp.DateKey=dd.DateKey
8 | WHERE da.AdjudicationCategory = 'DENIED'
9 | AND dd.MonthValue = 7;
10 |
11 | SELECT sum(fcp.DeniedCount) AS DeniedClaimCount
12 | FROM fact.ClaimPayment fcp
13 | INNER JOIN dim.Date dd ON fcp.DateKey=dd.DateKey
14 | WHERE dd.MonthValue = 7;
15 |
16 | SELECT dp.OrganizationName, sum(fcp. AutoAdjudicatedCount) AS AutoAdjudicatedCount
17 | FROM fact.ClaimPayment fcp
18 | INNER JOIN dim.Provider dp ON fcp.ProviderKey=dp.ProviderKey
19 | GROUP BY dp.OrganizationName;
20 |
21 | SELECT dp.OrganizationName,
22 | dd.MonthValue,
23 | sum(fcp. AutoAdjudicatedCount)/cast(count(ClaimID) as decimal(5,2))*100 AS AutoRatio
24 | FROM fact.ClaimPayment fcp
25 | INNER JOIN dim.Provider dp ON fcp.ProviderKey=dp.ProviderKey
26 | INNER JOIN dim.Date dd ON fcp.DateKey=dd.DateKey
27 | WHERE dd.DateValue between '01/01/2016' and '12/31/2016'
28 | GROUP BY dp.OrganizationName, dd.MonthValue;
29 |
30 | SELECT dd.DateValue, dm.InsuranceNumber, dat.AdjudicationType,
31 | dp.OrganizationName, ddiag.DiagnosisCode, dhcpc.ProcedureCode,
32 | SUM(fcp.ClaimAmount) AS ClaimAmount,
33 | SUM(fcp.AutoPayoutAmount) AS AutoPaymountAmount,
34 | SUM(fcp.ManualPayoutAmount) AS ManualPayoutAmount,
35 | SUM(fcp.AutoAdjudicatedCount) AS AutoAdjudicatedCount,
36 | SUM(fcp.ManualAdjudicatedCount) AS ManualAdjudicatedCount,
37 | SUM(fcp.AcceptedCount) AS AcceptedCount,
38 | SUM(fcp.DeniedCount) AS DeniedCount
39 | FROM fact.ClaimPayment fcp
40 | INNER JOIN dim.Date dd ON fcp.DateKey=dd.DateKey
41 | INNER JOIN dim.Member dm ON fcp.MemberKey=dm.MemberKey
42 | INNER JOIN dim.AdjudicationType dat ON fcp.AdjudicationTypeKey=dat.AdjudicationTypeKey
43 | INNER JOIN dim.Provider dp ON fcp.ProviderKey=dp.ProviderKey
44 | INNER JOIN dim.Diagnosis ddiag ON fcp.DiagnosisKey=ddiag.DiagnosisKey
45 | INNER JOIN dim.HCPCSProcedure dhcpc ON fcp.ProcedureKey=dhcpc.ProcedureKey
46 | GROUP BY dd.DateValue, dm.InsuranceNumber, dat.AdjudicationType,
47 | dp.OrganizationName, ddiag.DiagnosisCode, dhcpc.ProcedureCode;
48 |
49 | SELECT ProcedureKey, SUM(ClaimAmount) AS ClaimByProcedure
50 | FROM fact.ClaimPayment
51 | GROUP BY ProcedureKey;
52 |
53 | CREATE NONCLUSTERED INDEX NonClusteredIndex ON fact.ClaimPayment
54 | (
55 | ProcedureKey ASC
56 | );
57 | GO
58 |
59 | CREATE NONCLUSTERED COLUMNSTORE INDEX ColumnStoreIndex ON fact.ClaimPayment
60 | (
61 | DateKey,
62 | MemberKey,
63 | AdjudicationTypeKey,
64 | ProviderKey,
65 | DiagnosisKey,
66 | ProcedureKey,
67 | ClaimID,
68 | ClaimAmount,
69 | AutoPayoutAmount,
70 | ManualPayoutAmount,
71 | AutoAdjudicatedCount,
72 | ManualAdjudicatedCount,
73 | AcceptedCount,
74 | DeniedCount
75 | );
76 | GO
77 |
--------------------------------------------------------------------------------
/Code/Chapter 14/Operational DDL and Load and Query and Index Script.sql:
--------------------------------------------------------------------------------
1 | USE [Chapter14];
2 | GO
3 |
4 | -- Create In-memory OLTP tables
5 | CREATE TABLE [dbo].[AdjudicationType](
6 | [AdjudicationTypeID] [int] IDENTITY(1,1) NOT NULL PRIMARY KEY NONCLUSTERED,
7 | [AdjudicationType] [varchar](50) NOT NULL,
8 | [ModifiedDate] [datetime] NOT NULL
9 | ) WITH
10 | (MEMORY_OPTIMIZED = ON,
11 | DURABILITY = SCHEMA_AND_DATA);
12 | GO
13 |
14 | CREATE TABLE [dbo].[Member](
15 | [MemberID] [int] IDENTITY(1,1) NOT NULL PRIMARY KEY NONCLUSTERED,
16 | [CardNumber] [varchar](10) NOT NULL,
17 | [FirstName] [varchar](50) NOT NULL,
18 | [MiddleName] [varchar](50) NULL,
19 | [LastName] [varchar](50) NOT NULL,
20 | [Suffix] [varchar](10) NULL,
21 | [EmailAddress] [varchar](40) NULL,
22 | [ModifiedDate] [datetime] NOT NULL
23 | ) WITH
24 | (MEMORY_OPTIMIZED = ON,
25 | DURABILITY = SCHEMA_AND_DATA);
26 | GO
27 |
28 | CREATE TABLE [dbo].[Claim](
29 | [ClaimID] [int] IDENTITY(1,1) NOT NULL PRIMARY KEY NONCLUSTERED,
30 | [ReceivedDate] [datetime] NOT NULL,
31 | [DecisionDate] [datetime] NOT NULL,
32 | [MemberID] [int] NULL,
33 | [AdjudicationTypeID] [int] NOT NULL,
34 | [ClaimPayment] [money] NOT NULL,
35 | [ModifiedDate] [datetime] NOT NULL
36 | ) WITH
37 | (MEMORY_OPTIMIZED = ON,
38 | DURABILITY = SCHEMA_AND_DATA);
39 | GO
40 |
41 | ALTER TABLE [dbo].[Claim] WITH CHECK
42 | ADD CONSTRAINT [FK_dboClaim_AdjudicationType] FOREIGN KEY([AdjudicationTypeID])
43 | REFERENCES [dbo].[AdjudicationType] ([AdjudicationTypeID]);
44 | GO
45 |
46 | ALTER TABLE [dbo].[Claim] CHECK CONSTRAINT [FK_dboClaim_AdjudicationType];
47 | GO
48 |
49 | ALTER TABLE [dbo].[Claim] WITH CHECK
50 | ADD CONSTRAINT [FK_dboClaim_Member] FOREIGN KEY([MemberID])
51 | REFERENCES [dbo].[Member] ([MemberID]);
52 | GO
53 |
54 | ALTER TABLE [dbo].[Claim] CHECK CONSTRAINT [FK_dboClaim_Member];
55 | GO
56 |
57 | -- Load AdjudicationType Table
58 | INSERT INTO AdjudicationType VALUES ('AUTO', getdate());
59 | GO
60 |
61 | INSERT INTO AdjudicationType VALUES ('MANUAL', getdate());
62 | GO
63 |
64 |
65 | -- Load Member Table
66 | INSERT INTO [dbo].[Member] ([CardNumber], [FirstName], [MiddleName],
67 | [LastName], [Suffix], [EmailAddress], [ModifiedDate])
68 | VALUES ('ANT48963', 'Jessica', 'Diane', 'Moss', 'Ms.', 'jessica@email.com', getdate());
69 | GO
70 |
71 | INSERT INTO [dbo].[Member] ([CardNumber], [FirstName], [MiddleName],
72 | [LastName], [Suffix], [EmailAddress], [ModifiedDate])
73 | VALUES ('ANT8723', 'Richard', 'John', 'Smith', 'Mr.', 'richard@email.com', getdate());
74 | GO
75 |
76 | INSERT INTO [dbo].[Member] ([CardNumber], [FirstName], [MiddleName],
77 | [LastName], [Suffix], [EmailAddress], [ModifiedDate])
78 | VALUES ('BCBS8723', 'Paulette', 'Lara', 'Jones', 'Mrs.', 'paulette@email.com', getdate());
79 | GO
80 |
81 | -- Load Claim Table
82 | DECLARE @i AS INT;
83 | SET @i = 0;
84 |
85 | WHILE @i < 250000
86 | BEGIN
87 | INSERT INTO [dbo].[Claim] ([ReceivedDate], [DecisionDate], [MemberID]
88 | ,[AdjudicationTypeID], [ClaimPayment], [ModifiedDate])
89 | VALUES (DATEADD(day, cast((rand()*100) as int) % 28 + 1
90 | , DATEADD(month, cast((rand()*100) as int) % 12 + 1, '2016-01-01'))
91 | , DATEADD(day, cast((rand()*100) as int) % 28 + 1
92 | , DATEADD(month, cast((rand()*100) as int) % 12 + 1, '2016-01-01'))
93 | , cast((rand()*100) as int) % 3 + 1
94 | , cast((rand()*100) as int) % 2 + 1
95 | , cast((rand()*1000) as decimal(5, 2))
96 | , getdate())
97 | SET @i = @i + 1
98 | END;
99 | GO
100 |
101 | -- Queries and Indexes
102 | SELECT count(m.CardNumber) AS ClaimCount
103 | FROM dbo.Claim AS c
104 | LEFT JOIN dbo.AdjudicationType AS adj ON c.AdjudicationTypeID = adj.AdjudicationTypeID
105 | LEFT JOIN dbo.Member AS m ON c.MemberID = m.MemberID
106 | WHERE AdjudicationType = 'MANUAL';
107 |
108 | SELECT AdjudicationType, SUM(ClaimPayment) AS TotalAmt
109 | FROM dbo.Claim AS c
110 | LEFT JOIN dbo.AdjudicationType AS adj ON c.AdjudicationTypeID = adj.AdjudicationTypeID
111 | LEFT JOIN dbo.Member AS m on c.MemberID = m.MemberID
112 | WHERE DecisionDate > DATEADD(year, -1, getdate())
113 | GROUP BY AdjudicationType;
114 |
115 | -- Create Columnstore Tables
116 | CREATE TABLE [dbo].[Claim_Columnstore]
117 | (
118 | [ClaimID] [int] IDENTITY(1,1) NOT NULL,
119 | [ReceivedDate] [datetime] NOT NULL,
120 | [DecisionDate] [datetime] NOT NULL,
121 | [MemberID] [int] NULL,
122 | [AdjudicationTypeID] [int] NOT NULL,
123 | [ClaimPayment] [money] NOT NULL,
124 | [ModifiedDate] [datetime] NOT NULL,
125 | PRIMARY KEY NONCLUSTERED
126 | (
127 | [ClaimID] ASC
128 | ),
129 | INDEX IX_COLUMNSTORE CLUSTERED COLUMNSTORE
130 | ) WITH ( MEMORY_OPTIMIZED = ON , DURABILITY = SCHEMA_AND_DATA );
131 |
132 | GO
133 |
134 | ALTER TABLE [dbo].[Claim_Columnstore] WITH CHECK
135 | ADD CONSTRAINT [FK_dboClaimColumnstore_AdjudicationType]
136 | FOREIGN KEY([AdjudicationTypeID])
137 | REFERENCES [dbo].[AdjudicationType] ([AdjudicationTypeID]);
138 | GO
139 |
140 | ALTER TABLE [dbo].[Claim_Columnstore]
141 | CHECK CONSTRAINT [FK_dboClaimColumnstore_AdjudicationType];
142 | GO
143 |
144 | ALTER TABLE [dbo].[Claim_Columnstore] WITH CHECK
145 | ADD CONSTRAINT [FK_dboClaimColumnstore_Member]
146 | FOREIGN KEY([MemberID])
147 | REFERENCES [dbo].[Member] ([MemberID]);
148 | GO
149 |
150 | ALTER TABLE [dbo].[Claim_Columnstore]
151 | CHECK CONSTRAINT [FK_dboClaimColumnstore_Member];
152 | GO
153 |
154 | -- Use Columnstore tables
155 | SELECT count(m.CardNumber) AS ClaimCount
156 | FROM dbo.Claim_Columnstore AS c
157 | LEFT JOIN dbo.AdjudicationType AS adj ON c.AdjudicationTypeID = adj.AdjudicationTypeID
158 | LEFT JOIN dbo.Member AS m ON c.MemberID = m.MemberID
159 | WHERE AdjudicationType = 'MANUAL';
160 |
161 | SELECT AdjudicationType, SUM(ClaimPayment) AS TotalAmt
162 | FROM dbo.Claim_Columnstore AS c
163 | LEFT JOIN dbo.AdjudicationType AS adj ON c.AdjudicationTypeID = adj.AdjudicationTypeID
164 | LEFT JOIN dbo.Member AS m on c.MemberID = m.MemberID
165 | WHERE DecisionDate > DATEADD(year, -1, getdate())
166 | GROUP BY AdjudicationType;
167 |
--------------------------------------------------------------------------------
/Code/Chapter 06-TestScriptOnly.sql:
--------------------------------------------------------------------------------
1 | SET NOCOUNT ON;
2 | USE ConferenceMessaging;
3 | GO
4 | DELETE FROM Messages.MessageTopic ;
5 | DELETE FROM Messages.Message;
6 | DELETE FROM Messages.Topic WHERE TopicId <> 0; --Leave the User Defined Topic
7 | DELETE FROM Attendees.UserConnection;
8 | DELETE FROM Attendees.MessagingUser;
9 |
10 | GO
11 |
12 | INSERT INTO [Attendees].[MessagingUser]
13 | ([UserHandle],[AccessKeyValue],[AttendeeNumber]
14 | ,[FirstName],[LastName],[AttendeeType]
15 | ,[DisabledFlag])
16 | VALUES ('FredF','0000000000','00000000','Fred','Flintstone','Regular',0)
17 |
18 | IF @@ROWCOUNT <> 1 THROW 50000,'Attendees.MessagingUser Single Row Failed',16
19 | GO
20 |
21 | BEGIN TRY --Check UserHandle Check Constraint
22 | INSERT INTO [Attendees].[MessagingUser]
23 | ([UserHandle],[AccessKeyValue],[AttendeeNumber]
24 | ,[FirstName],[LastName],[AttendeeType]
25 | ,[DisabledFlag])
26 | VALUES ('Wil','0000000000','00000001','Wilma','Flintstone','Regular',0);
27 | THROW 50000,'No error raised',16;
28 | END TRY
29 | BEGIN CATCH
30 | if ERROR_MESSAGE() not like
31 | '%CHKMessagingUser_UserHandle_LengthAndStart%'
32 | THROW 50000,'Check Messages.Topic.Name didn''t work',16;
33 | END CATCH
34 | GO
35 |
36 | BEGIN TRY --Check UserHandle Check Constraint
37 | INSERT INTO [Attendees].[MessagingUser]
38 | ([UserHandle],[AccessKeyValue],[AttendeeNumber]
39 | ,[FirstName],[LastName],[AttendeeType]
40 | ,[DisabledFlag])
41 | VALUES ('Wilma@','0000000000','00000001','Wilma','Flintstone','Regular',0);
42 | THROW 50000,'No error raised',16;
43 | End TRY
44 | BEGIN CATCH
45 | if ERROR_MESSAGE() not like
46 | '%CHKMessagingUser_UserHandle_LengthAndStart%'
47 | THROW 50000,'Check Messages.Topic.Name didn''t work',16;
48 | END CATCH
49 | GO
50 |
51 |
52 |
53 | BEGIN TRY --Check UserHandle Check Constraint
54 | INSERT INTO [Attendees].[MessagingUser]
55 | ([UserHandle],[AccessKeyValue],[AttendeeNumber]
56 | ,[FirstName],[LastName],[AttendeeType]
57 | ,[DisabledFlag])
58 | VALUES ('Wil','0000000000','00000001','Wilma','Flintstone','Regular',0);
59 | THROW 50000,'No error raised',16;
60 | End TRY
61 | BEGIN CATCH
62 | if ERROR_MESSAGE() not like '%CHKMessagingUser_UserHandle_LengthAndStart%'
63 | THROW 50000,'Check Messages.Topic.Name didn''t work',16
64 | END CATCH
65 | GO
66 | BEGIN TRY --Check UserHandle Check Constraint
67 | INSERT INTO [Attendees].[MessagingUser]
68 | ([UserHandle],[AccessKeyValue],[AttendeeNumber]
69 | ,[FirstName],[LastName],[AttendeeType]
70 | ,[DisabledFlag])
71 | VALUES ('Wilma@','0000000000','00000001','Wilma','Flintstone','Regular',0);
72 | THROW 50000,'No error raised',16;
73 | End TRY
74 | BEGIN CATCH
75 | if ERROR_MESSAGE() not like '%CHKMessagingUser_UserHandle_LengthAndStart%'
76 | THROW 50000,'Check Messages.Topic.Name didn''t work',16;
77 | END CATCH
78 | GO
79 |
80 | INSERT INTO [Attendees].[MessagingUser]
81 | ([UserHandle],[AccessKeyValue],[AttendeeNumber]
82 | ,[FirstName],[LastName],[AttendeeType]
83 | ,[DisabledFlag])
84 | VALUES ('WilmaF','0000000000','00000001','Wilma','Flintstone','Regular',0),
85 | ('BarneyR','0000000000','00000002','Barney','Rubble','Regular',0),
86 | ('BettyR22','0000000000','00000003','Betty','Rubble','Speaker',0),
87 | ('SSlate','000000000','00000004','Sam','Slate','Regular',0),
88 | ('JimRocky','000000000','00000005','Jim','Rock','Administrator',0);
89 |
90 | if @@ROWCOUNT <> 5 THROW 50000,'Attendees.MessagingUser Multi Row Failed',16;
91 |
92 | waitfor delay '00:00:03' --to make sure the update time is different
93 |
94 | UPDATE Attendees.MessagingUser
95 | SET AttendeeType = case when UserHandle = 'BettyR22' then 'Regular'
96 | when UserHandle = 'SSlate' then 'Speaker'
97 | end
98 | WHERE UserHandle in ('BettyR22','SSlate')
99 |
100 | if @@ROWCOUNT <> 2 THROW 50000,'Attendees.MessagingUser Multi Row Update Failed',16
101 |
102 | insert into Attendees.UserConnection (MessagingUserId,ConnectedToMessagingUserId)
103 | select MessagingUser.MessagingUserId, ConnectedTo.MessagingUserId
104 | from Attendees.MessagingUser
105 | cross join Attendees.MessagingUser as ConnectedTo
106 | where MessagingUser.UserHandle = 'FredF'
107 | and ConnectedTo.UserHandle = 'WilmaF';
108 |
109 | if @@ROWCOUNT <> 1 THROW 50000,'Attendees.UserConnection Single Row Update Failed',16;
110 |
111 | insert into Attendees.UserConnection (MessagingUserId,ConnectedToMessagingUserId)
112 | select MessagingUser.MessagingUserId, ConnectedTo.MessagingUserId
113 | from Attendees.MessagingUser
114 | cross join Attendees.MessagingUser as ConnectedTo
115 | where MessagingUser.UserHandle = 'WilmaF'
116 | and MessagingUser.MessagingUserId <> ConnectedTo.MessagingUserId;
117 |
118 | if @@ROWCOUNT <> 5 THROW 50000,'Attendees.UserConnection Multi Row Update Failed',16;
119 |
120 | Insert into Messages.Topic(Name, Description)
121 | Values ('General','General Messages')
122 |
123 | if @@ROWCOUNT <> 1 THROW 50000,'Messages.Topic Single Row Update Failed',16
124 |
125 | BEGIN TRY --Check Messages.Topic.Name Check Constraint
126 | Insert into Messages.Topic(Name, Description)
127 | Values (' ','General Messages');
128 | THROW 50000,'No error raised',16;
129 | End TRY
130 | BEGIN CATCH
131 | if ERROR_MESSAGE() not like '%CHKTopic_Name_NotEmpty%'
132 | THROW 50000,'Check Messages.Topic.Name didn''t work',16
133 | END CATCH
134 | GO
135 |
136 |
137 | INSERT INTO Messages.Topic(Name, Description)
138 | VALUES ('Misc','Miscelaneous'),
139 | ('Special','Special Topic');
140 |
141 | if @@ROWCOUNT <> 2 THROW 50000, 'Messages.Topic MultiRow Update Failed',16;
142 |
143 | GO
144 |
145 |
146 | INSERT INTO [Messages].[Message]
147 | ([MessagingUserId]
148 | ,[SentToMessagingUserId]
149 | ,[Text]
150 | ,[MessageTime])
151 | VALUES
152 | ((select MessagingUserId from Attendees.MessagingUser where UserHandle = 'FredF')
153 | ,(select MessagingUserId from Attendees.MessagingUser where UserHandle = 'WilmaF')
154 | ,'It looks like I will be late tonight'
155 | ,GETDATE());
156 |
157 | IF @@ROWCOUNT <> 1 THROW 50000,'Messages.Messages Single Insert Failed',16;
158 | GO
159 |
160 | GO
161 |
162 | BEGIN TRY --Unique Message Error...
163 | INSERT INTO [Messages].[Message]
164 | ([MessagingUserId]
165 | ,[SentToMessagingUserId]
166 | ,[Text]
167 | ,[MessageTime])
168 | VALUES
169 | ((SELECT MessagingUserId FROM Attendees.MessagingUser
170 | WHERE UserHandle = 'FredF')
171 | ,(SELECT MessagingUserId FROM Attendees.MessagingUser
172 | WHERE UserHandle = 'WilmaF')
173 | ,'It looks like I will be late tonight'
174 | ,GETDATE());
175 | THROW 50000,'No error raised',16;
176 | END TRY
177 | BEGIN CATCH
178 | if ERROR_MESSAGE() NOT LIKE '%AKMessage_TimeUserAndText%'
179 | THROW 50000,'Unique Message Error didn''t work (check times)',16;
180 | END CATCH
181 | GO
182 |
183 | INSERT INTO [Messages].[Message]
184 | ([MessagingUserId]
185 | ,[SentToMessagingUserId]
186 | ,[Text]
187 | ,[MessageTime])
188 | VALUES
189 | ((select MessagingUserId from Attendees.MessagingUser where UserHandle = 'WilmaF')
190 | ,(select MessagingUserId from Attendees.MessagingUser where UserHandle = 'FredF')
191 | ,'I will kill you :)'
192 | ,GETDATE()),
193 | ((select MessagingUserId from Attendees.MessagingUser where UserHandle = 'BarneyR')
194 | ,(select MessagingUserId from Attendees.MessagingUser where UserHandle = 'BettyR22')
195 | ,'Fred and Wilma Are Nuts!'
196 | ,GETDATE());
197 |
198 | if @@ROWCOUNT <> 2 THROW 50000,'Messages.Messages MultiRow Update Failed',16
199 | GO
200 |
201 | declare @messagingUserId int, @text nvarchar(200),
202 | @messageTime datetime2, @RoundedMessageTime smalldatetime
203 | select @messagingUserId = (select MessagingUserId from Attendees.MessagingUser where UserHandle = 'FredF'),
204 | @text = 'Going bowling, don''t tell my wife!', @messageTime = GETDATE()
205 | select @RoundedMessageTime = (dateadd(hour,datepart(hour,@MessageTime),CONVERT(smalldatetime,CONVERT(date,@MessageTime))))
206 |
207 | INSERT INTO [Messages].[Message]
208 | ([MessagingUserId]
209 | ,[SentToMessagingUserId]
210 | ,[Text]
211 | ,[MessageTime])
212 | VALUES
213 | (@messagingUserId,NULL,@text, @messageTime);
214 |
215 | if @@ROWCOUNT <> 1 THROW 50000,'Messages.Messages Single Insert Failed',16;
216 |
217 | insert into Messages.MessageTopic(MessageId, TopicId)
218 | VALUES(
219 | (SELECT MessageId
220 | FROM Messages.Message
221 | WHERE MessagingUserId = @messagingUserId
222 | and Text = @text
223 | and RoundedMessageTime = @RoundedMessageTime), (SELECT TopicId
224 | FROM Messages.Topic
225 | WHERE Name = 'General'));
226 |
227 | if @@ROWCOUNT <> 1 THROW 50000,'Messages.MessageTopic Single Insert Failed',16;
228 | GO
229 |
230 | --Do this in a more natural way. Usually the client would pass in these values
231 | DECLARE @messagingUserId int, @text nvarchar(200),
232 | @messageTime datetime2, @RoundedMessageTime smalldatetime
233 |
234 | SELECT @messagingUserId = (SELECT MessagingUserId FROM Attendees.MessagingUser
235 | WHERE UserHandle = 'FredF'),
236 | @text = 'Oops Why Did I say That?', @messageTime = GETDATE()
237 |
238 | --uses the same algorithm as the check constraint to calculate part of the key
239 | SELECT @RoundedMessageTime = (
240 | DATEADD(HOUR,DATEPART(HOUR,@MessageTime),CONVERT(datetime2(0),CONVERT(date,@MessageTime))))
241 |
242 | BEGIN TRY
243 | BEGIN TRANSACTION
244 | --first create a new message
245 | INSERT INTO [Messages].[Message]
246 | ([MessagingUserId],[SentToMessagingUserId]
247 | ,[Text] ,[MessageTime])
248 | VALUES
249 | (@messagingUserId,NULL,@text, @messageTime)
250 |
251 | --then insert the topic,but this will fail because General topic is not
252 | --compatible with a UserDefinedTopicName value
253 | INSERT INTO Messages.MessageTopic(MessageId, TopicId, UserDefinedTopicName)
254 | VALUES(
255 | (SELECT MessageId
256 | FROM Messages.Message
257 | WHERE MessagingUserId = @messagingUserId
258 | AND Text = @text
259 | AND RoundedMessageTime = @RoundedMessageTime),
260 | (SELECT TopicId
261 | FROM Messages.Topic
262 | WHERE Name = 'General'),'Stupid Stuff')
263 |
264 | COMMIT TRANSACTION
265 | END TRY
266 | BEGIN CATCH
267 | if @@TRANCOUNT <> 0 ROLLBACK;
268 | if ERROR_MESSAGE() not like '%CHKMessageTopic_UserDefinedTopicName_NullUnlessUserDefined%'
269 | BEGIN
270 | THROW 50000,'UserDefined Message Check Failed',16;
271 | END
272 | END CATCH
273 | GO
274 |
275 | declare @messagingUserId int, @text nvarchar(200),
276 | @messageTime datetime2, @RoundedMessageTime smalldatetime
277 | select @messagingUserId = (select MessagingUserId from Attendees.MessagingUser where UserHandle = 'FredF'),
278 | @text = 'Oops Why Did I say That?', @messageTime = GETDATE()
279 | select @RoundedMessageTime = (dateadd(hour,datepart(hour,@MessageTime),CONVERT(smalldatetime,CONVERT(date,@MessageTime))))
280 |
281 | INSERT INTO [Messages].[Message]
282 | ([MessagingUserId]
283 | ,[SentToMessagingUserId]
284 | ,[Text]
285 | ,[MessageTime])
286 | VALUES
287 | (@messagingUserId,NULL,@text, @messageTime)
288 |
289 | if @@ROWCOUNT <> 1 THROW 50000,'Messages.Messages Single Insert Failed',16;
290 |
291 | INSERT into Messages.MessageTopic(MessageId, TopicId, UserDefinedTopicName)
292 | VALUES(
293 | (SELECT MessageId
294 | FROM Messages.Message
295 | WHERE MessagingUserId = @messagingUserId
296 | and Text = @text
297 | and RoundedMessageTime = @RoundedMessageTime), (SELECT TopicId
298 | FROM Messages.Topic
299 | WHERE Name = 'User Defined'),'Stupid Stuff');
300 |
301 | if @@ROWCOUNT <> 1 THROW 50000,'Messages.MessageTopic Single Insert Failed',16;
302 | GO
303 |
304 | select *
305 | from Attendees.AttendeeType
306 |
307 | select *
308 | from Attendees.MessagingUser
309 |
310 | select *
311 | from Attendees.UserConnection
312 |
313 | select *
314 | from Messages.Topic
315 |
316 | SELECT *
317 | from Messages.Message
318 |
319 | SELECT *
320 | from Messages.MessageTopic
--------------------------------------------------------------------------------
/Code/Chapter 14/Analytical Dimensional DDL and Load Script.sql:
--------------------------------------------------------------------------------
1 | -- Create separate database for this chapter
2 | CREATE DATABASE [Chapter14];
3 | GO
4 |
5 | USE [Chapter14];
6 | GO
7 |
8 | -- Create schema for all dimension tables
9 | CREATE SCHEMA dim;
10 | GO
11 |
12 | -- Create Date Dimension
13 | CREATE TABLE dim.Date
14 | (
15 | DateKey INTEGER NOT NULL,
16 | DateValue DATE NOT NULL,
17 | DayValue INTEGER NOT NULL,
18 | WeekValue INTEGER NOT NULL,
19 | MonthValue INTEGER NOT NULL,
20 | YearValue INTEGER NOT NULL
21 | CONSTRAINT PK_Date PRIMARY KEY CLUSTERED
22 | (
23 | DateKey ASC
24 | ));
25 | GO
26 |
27 | -- Create Date Dimension Load Stored Procedure
28 | CREATE PROCEDURE dim.LoadDate (@startDate DATETIME, @endDate DATETIME)
29 | AS
30 | BEGIN
31 |
32 | IF NOT EXISTS (SELECT * FROM dim.Date WHERE DateKey = -1)
33 | BEGIN
34 | INSERT INTO dim.Date
35 | SELECT -1, '01/01/1900', -1, -1, -1, -1;
36 | END
37 |
38 | WHILE @startdate <= @enddate
39 | BEGIN
40 | IF NOT EXISTS (SELECT * FROM dim.Date WHERE DateValue = @startdate)
41 | BEGIN
42 | INSERT INTO dim.Date
43 | SELECT CONVERT(CHAR(8), @startdate, 112) AS DateKey
44 | ,@startdate AS DateValue
45 | ,DAY(@startdate) AS DayValue
46 | ,DATEPART(wk, @startdate) AS WeekValue
47 | ,MONTH(@startdate) AS MonthValue
48 | ,YEAR(@startdate) AS YearValue
49 | SET @startdate = DATEADD(dd, 1, @startdate);
50 | END
51 | END
52 | END;
53 | GO
54 |
55 | --Execute the Data Dimension Load Stored Procedure
56 | EXECUTE dim.LoadDate '01/01/2016', '12/31/2017';
57 | GO
58 |
59 | -- Create the Member dimension table
60 | CREATE TABLE dim.Member
61 | (
62 | MemberKey INTEGER NOT NULL IDENTITY(1,1),
63 | InsuranceNumber VARCHAR(12) NOT NULL,
64 | FirstName VARCHAR(50) NOT NULL,
65 | LastName VARCHAR(50) NOT NULL,
66 | PrimaryCarePhysician VARCHAR(100) NOT NULL,
67 | County VARCHAR(40) NOT NULL,
68 | StateCode CHAR(2) NOT NULL,
69 | MembershipLength VARCHAR(15) NOT NULL
70 | CONSTRAINT PK_Member PRIMARY KEY CLUSTERED
71 | (
72 | MemberKey ASC
73 | ));
74 | GO
75 |
76 | -- Load Member dimension table
77 | SET IDENTITY_INSERT [dim].[Member] ON;
78 | GO
79 | INSERT INTO [dim].[Member]
80 | ([MemberKey],[InsuranceNumber],[FirstName],[LastName],[PrimaryCarePhysician]
81 | ,[County],[StateCode],[MembershipLength])
82 | SELECT -1, 'UNKNOWN','UNKNOWN','UNKNOWN','UNKNOWN','UNKNOWN','UN','UNKNOWN'
83 | UNION ALL
84 | SELECT 1, 'IN438973','Brandon','Jones','Dr. Keiser & Associates','Henrico','VA','<1 year'
85 | UNION ALL
86 | SELECT 2, 'IN958394','Nessa','Gomez','Healthy Lifestyles','Henrico','VA','1-2 year'
87 | UNION ALL
88 | SELECT 3, 'IN3867910','Catherine','Patten','Dr. Jenny Stevens','Spotsylvania','VA','<1 year';
89 | GO
90 | SET IDENTITY_INSERT [dim].[Member] OFF;
91 | GO
92 |
93 | ALTER TABLE dim.Member
94 | ADD isCurrent INTEGER NOT NULL DEFAULT 1;
95 | GO
96 |
97 | INSERT INTO [dim].[Member]
98 | ([InsuranceNumber],[FirstName],[LastName],[PrimaryCarePhysician]
99 | ,[County],[StateCode],[MembershipLength])
100 | VALUES
101 | ('IN438973','Brandon','Jones','Dr. Jenny Stevens','Henrico','VA','<1 year');
102 | GO
103 |
104 | UPDATE [dim].[Member] SET isCurrent = 0
105 | WHERE InsuranceNumber = 'IN438973' AND PrimaryCarePhysician = 'Dr. Keiser & Associates';
106 | GO
107 |
108 | -- Create the Provider dimension table
109 | CREATE TABLE dim.Provider (
110 | ProviderKey INTEGER IDENTITY(1,1) NOT NULL,
111 | NPI VARCHAR(10) NOT NULL,
112 | EntityTypeCode INTEGER NOT NULL,
113 | EntityTypeDesc VARCHAR(12) NOT NULL, -- (1:Individual,2:Organization)
114 | OrganizationName VARCHAR(70) NOT NULL,
115 | DoingBusinessAsName VARCHAR(70) NOT NULL,
116 | Street VARCHAR(55) NOT NULL,
117 | City VARCHAR(40) NOT NULL,
118 | State VARCHAR(40) NOT NULL,
119 | Zip VARCHAR(20) NOT NULL,
120 | Phone VARCHAR(20) NOT NULL,
121 | isCurrent INTEGER NOT NULL DEFAULT 1
122 | CONSTRAINT PK_Provider PRIMARY KEY CLUSTERED
123 | (
124 | ProviderKey ASC
125 | ));
126 | GO
127 |
128 | -- Insert sample data into Provider dimension table
129 | SET IDENTITY_INSERT [dim].[Provider] ON;
130 | GO
131 | INSERT INTO [dim].[Provider]
132 | ([ProviderKey],[NPI],[EntityTypeCode],[EntityTypeDesc],[OrganizationName],
133 | [DoingBusinessAsName],[Street],[City],[State],[Zip],[Phone])
134 | SELECT -1, 'UNKNOWN',-1,'UNKNOWN','UNKNOWN','UNKNOWN',
135 | 'UNKNOWN','UNKNOWN','UNKNOWN','UNKNOWN','UNKNOWN'
136 | UNION ALL
137 | SELECT 1, '1234567',1,'Individual','Patrick Lyons','Patrick Lyons',
138 | '80 Park St.','Boston','Massachusetts','55555','555-123-1234'
139 | UNION ALL
140 | SELECT 2, '2345678',1,'Individual','Lianna White, LLC','Dr. White & Associates',
141 | '74 West Pine Ave.','Waltham','Massachusetts','55542','555-123-0012'
142 | UNION ALL
143 | SELECT 3, '76543210',2,'Organization','Doctors Conglomerate, Inc','Family Doctors',
144 | '25 Main Street Suite 108','Boston','Massachusetts','55555','555-321-4321'
145 | UNION ALL
146 | SELECT 4, '3456789',1,'Individual','Dr. Drew Adams','Dr. Drew Adams',
147 | '1207 Corporate Center','Peabody','Massachusetts','55554','555-234-1234';
148 | SET IDENTITY_INSERT [dim].[Provider] OFF;
149 | GO
150 |
151 | -- Create the Benefit dimension table
152 | CREATE TABLE dim.Benefit(
153 | BenefitKey INTEGER IDENTITY(1,1) NOT NULL,
154 | BenefitCode INTEGER NOT NULL,
155 | BenefitName VARCHAR(35) NOT NULL,
156 | BenefitSubtype VARCHAR(20) NOT NULL,
157 | BenefitType VARCHAR(20) NOT NULL
158 | CONSTRAINT PK_Benefit PRIMARY KEY CLUSTERED
159 | (
160 | BenefitKey ASC
161 | ));
162 | GO
163 |
164 | -- Create the Health Plan dimension table
165 | CREATE TABLE dim.HealthPlan(
166 | HealthPlanKey INTEGER IDENTITY(1,1) NOT NULL,
167 | HealthPlanIdentifier CHAR(4) NOT NULL,
168 | HealthPlanName VARCHAR(35) NOT NULL
169 | CONSTRAINT PK_HealthPlan PRIMARY KEY CLUSTERED
170 | (
171 | HealthPlanKey ASC
172 | ));
173 | GO
174 |
175 | ALTER TABLE dim.Benefit
176 | ADD HealthPlanKey INTEGER;
177 | GO
178 |
179 | ALTER TABLE dim.Benefit WITH CHECK
180 | ADD CONSTRAINT FK_Benefit_HealthPlan
181 | FOREIGN KEY(HealthPlanKey) REFERENCES dim.HealthPlan (HealthPlanKey);
182 | GO
183 | -- Insert sample data into Health plan dimension
184 | SET IDENTITY_INSERT [dim].[HealthPlan] ON;
185 | GO
186 | INSERT INTO [dim].[HealthPlan]
187 | ([HealthPlanKey], [HealthPlanIdentifier],[HealthPlanName])
188 | SELECT 1, 'BRON','Bronze Plan'
189 | UNION ALL
190 | SELECT 2, 'SILV','Silver Plan'
191 | UNION ALL
192 | SELECT 3, 'GOLD','Gold Plan';
193 | GO
194 | SET IDENTITY_INSERT [dim].[HealthPlan] OFF;
195 | GO
196 |
197 | -- Create the AdjudicationType dimension table
198 | CREATE TABLE dim.AdjudicationType (
199 | AdjudicationTypeKey INTEGER IDENTITY(1,1) NOT NULL,
200 | AdjudicationType VARCHAR(6) NOT NULL,
201 | AdjudicationCategory VARCHAR(8) NOT NULL
202 | CONSTRAINT PK_AdjudicationType PRIMARY KEY CLUSTERED
203 | (
204 | AdjudicationTypeKey ASC
205 | ));
206 | GO
207 |
208 | -- Insert values for the AdjudicationType dimension
209 | SET IDENTITY_INSERT dim.AdjudicationType ON;
210 | GO
211 | INSERT INTO dim.AdjudicationType
212 | (AdjudicationTypeKey, AdjudicationType, AdjudicationCategory)
213 | SELECT -1, 'UNKNWN', 'UNKNOWN'
214 | UNION ALL
215 | SELECT 1, 'AUTO', 'ACCEPTED'
216 | UNION ALL
217 | SELECT 2, 'MANUAL', 'ACCEPTED'
218 | UNION ALL
219 | SELECT 3, 'AUTO', 'DENIED'
220 | UNION ALL
221 | SELECT 4, 'MANUAL', 'DENIED';
222 | GO
223 | SET IDENTITY_INSERT dim.AdjudicationType OFF;
224 | GO
225 |
226 |
227 | -- Create Diagnosis dimension table
228 | CREATE TABLE dim.Diagnosis(
229 | DiagnosisKey int IDENTITY(1,1) NOT NULL,
230 | DiagnosisCode char(7) NULL,
231 | ShortDesc varchar(60) NULL,
232 | LongDesc varchar(350) NULL,
233 | OrderNumber int NULL,
234 | CONSTRAINT PK_Diagnosis PRIMARY KEY CLUSTERED
235 | (
236 | DiagnosisKey ASC
237 | ));
238 | GO
239 |
240 | -- Create HCPCSProcedure dimension table
241 | CREATE TABLE dim.HCPCSProcedure (
242 | ProcedureKey INTEGER IDENTITY(1,1) NOT NULL,
243 | ProcedureCode CHAR(5) NOT NULL,
244 | ShortDesc VARCHAR(28) NOT NULL,
245 | LongDesc VARCHAR(80) NOT NULL
246 | CONSTRAINT PK_HCPCSProcedure PRIMARY KEY CLUSTERED
247 | (
248 | ProcedureKey ASC
249 | ));
250 | GO
251 |
252 | -- Create schema for all fact tables
253 | CREATE SCHEMA fact;
254 | GO
255 |
256 | -- Create Claim Payment transaction fact table
257 | CREATE TABLE fact.ClaimPayment
258 | (
259 | DateKey INTEGER NOT NULL,
260 | MemberKey INTEGER NOT NULL,
261 | AdjudicationTypeKey INTEGER NOT NULL,
262 | ProviderKey INTEGER NOT NULL,
263 | DiagnosisKey INTEGER NOT NULL,
264 | ProcedureKey INTEGER NOT NULL,
265 | ClaimID VARCHAR(8) NOT NULL,
266 | ClaimAmount DECIMAL(10,2) NOT NULL,
267 | AutoPayoutAmount DECIMAL(10,2) NOT NULL,
268 | ManualPayoutAmount DECIMAL(10,2) NOT NULL,
269 | AutoAdjudicatedCount INTEGER NOT NULL,
270 | ManualAdjudicatedCount INTEGER NOT NULL,
271 | AcceptedCount INTEGER NOT NULL,
272 | DeniedCount INTEGER NOT NULL
273 | );
274 | GO
275 |
276 | -- Add foreign keys from ClaimPayment fact to dimensions
277 | ALTER TABLE fact.ClaimPayment WITH CHECK
278 | ADD CONSTRAINT FK_ClaimPayment_AdjudicationType
279 | FOREIGN KEY(AdjudicationTypeKey) REFERENCES dim.AdjudicationType (AdjudicationTypeKey);
280 | GO
281 |
282 | ALTER TABLE fact.ClaimPayment WITH CHECK
283 | ADD CONSTRAINT FK_ClaimPayment_Date
284 | FOREIGN KEY(DateKey) REFERENCES dim.Date (DateKey);
285 | GO
286 |
287 | ALTER TABLE fact.ClaimPayment WITH CHECK
288 | ADD CONSTRAINT FK_ClaimPayment_Diagnosis
289 | FOREIGN KEY(DiagnosisKey) REFERENCES dim.Diagnosis (DiagnosisKey);
290 | GO
291 |
292 | ALTER TABLE fact.ClaimPayment WITH CHECK
293 | ADD CONSTRAINT FK_ClaimPayment_HCPCSProcedure
294 | FOREIGN KEY(ProcedureKey) REFERENCES dim.HCPCSProcedure (ProcedureKey);
295 | GO
296 |
297 | ALTER TABLE fact.ClaimPayment WITH CHECK
298 | ADD CONSTRAINT FK_ClaimPayment_Member
299 | FOREIGN KEY(MemberKey) REFERENCES dim.Member (MemberKey);
300 | GO
301 |
302 | ALTER TABLE fact.ClaimPayment WITH CHECK
303 | ADD CONSTRAINT FK_ClaimPayment_Provider
304 | FOREIGN KEY(ProviderKey) REFERENCES dim.Provider (ProviderKey);
305 | GO
306 |
307 | -- Insert sample data into ClaimPayment fact table
308 | DECLARE @i INT;
309 | SET @i = 0;
310 |
311 | WHILE @i < 1000
312 | BEGIN
313 | INSERT INTO fact.ClaimPayment
314 | (
315 | DateKey, MemberKey, AdjudicationTypeKey, ProviderKey, DiagnosisKey,
316 | ProcedureKey, ClaimID, ClaimAmount, AutoPayoutAmount, ManualPayoutAmount,
317 | AutoAdjudicatedCount, ManualAdjudicatedCount, AcceptedCount, DeniedCount
318 | )
319 | SELECT
320 | CONVERT(CHAR(8), DATEADD(dd, RAND() * -100, getdate()), 112),
321 | (SELECT CEILING((COUNT(*) - 1) * RAND()) from dim.Member),
322 | (SELECT CEILING((COUNT(*) - 1) * RAND()) from dim.AdjudicationType),
323 | (SELECT CEILING((COUNT(*) - 1) * RAND()) from dim.Provider),
324 | (SELECT CEILING((COUNT(*) - 1) * RAND()) from dim.Diagnosis),
325 | (SELECT CEILING((COUNT(*) - 1) * RAND()) from dim.HCPCSProcedure),
326 | 'CL' + CAST(@i AS VARCHAR(6)),
327 | RAND() * 100000,
328 | RAND() * 100000 * (@i % 2),
329 | RAND() * 100000 * ((@i+1) % 2),
330 | 0,
331 | 0,
332 | 0,
333 | 0;
334 | SET @i = @i + 1;
335 | END;
336 | GO
337 | UPDATE fact.ClaimPayment
338 | SET AutoAdjudicatedCount = CASE WHEN AdjudicationTypeKey IN (1,3) THEN 1 ELSE 0 END
339 | ,ManualAdjudicatedCount = CASE WHEN AdjudicationTypeKey IN (2,4) THEN 1 ELSE 0 END
340 | ,AcceptedCount = CASE WHEN AdjudicationTypeKey IN (1,2) THEN 1 ELSE 0 END
341 | ,DeniedCount = CASE WHEN AdjudicationTypeKey IN (3,4) THEN 1 ELSE 0 END
342 | FROM fact.ClaimPayment;
343 | GO
344 |
345 | -- Create Membership snapshot fact table
346 | CREATE TABLE fact.Membership (
347 | DateKey INTEGER NOT NULL,
348 | HealthPlanKey INTEGER NOT NULL,
349 | MemberAmount INTEGER NOT NULL
350 | );
351 | GO
352 |
353 | -- Add foreign keys from Membership fact to dimensions
354 | ALTER TABLE fact.Membership WITH CHECK
355 | ADD CONSTRAINT FK_Membership_Date
356 | FOREIGN KEY(DateKey) REFERENCES dim.Date (DateKey);
357 | GO
358 |
359 | ALTER TABLE fact.Membership WITH CHECK
360 | ADD CONSTRAINT FK_Membership_HealthPlan
361 | FOREIGN KEY(HealthPlanKey) REFERENCES dim.HealthPlan (HealthPlanKey);
362 | GO
363 |
364 | -- Insert sample data into the Membership fact table
365 | DECLARE @startdate DATE;
366 | DECLARE @enddate DATE;
367 | SET @startdate = '1/1/2016';
368 | SET @enddate = '12/31/2016';
369 |
370 | WHILE @startdate <= @enddate
371 | BEGIN
372 | INSERT INTO fact.Membership
373 | SELECT CONVERT(CHAR(8), @startdate, 112) AS DateKey
374 | ,1 AS HPKey
375 | ,RAND() * 1000 AS MemberAmount;
376 | INSERT INTO fact.Membership
377 | SELECT CONVERT(CHAR(8), @startdate, 112) AS DateKey
378 | ,2 AS HPKey
379 | ,RAND() * 1000 AS MemberAmount;
380 | INSERT INTO fact.Membership
381 | SELECT CONVERT(CHAR(8), @startdate, 112) AS DateKey
382 | ,3 AS HPKey
383 | ,RAND() * 1000 AS MemberAmount;
384 |
385 | SET @startdate = DATEADD(dd, 1, @startdate);
386 | END;
387 | GO
388 |
--------------------------------------------------------------------------------
/Code/Chapter 10.sql:
--------------------------------------------------------------------------------
1 | ---Indexing Overview
2 | ----Basic Index Structure
3 | ------On-Disk Indexes
4 |
5 | -------Clustered Indexes
6 |
7 | SET SHOWPLAN_TEXT ON;
8 | GO
9 | SELECT *
10 | FROM [Application].[Cities];
11 | GO
12 | SET SHOWPLAN_TEXT OFF
13 | GO
14 |
15 | SET SHOWPLAN_TEXT ON;
16 | GO
17 | SELECT *
18 | FROM [Application].[Cities]
19 | WHERE CityID = 23629; --A favorite city of mine, indeed.
20 | GO
21 | SET SHOWPLAN_TEXT OFF
22 |
23 | SET SHOWPLAN_TEXT ON;
24 | GO
25 | SELECT *
26 | FROM [Application].[Cities]
27 | WHERE CityID IN (23629,334);
28 | GO
29 | SET SHOWPLAN_TEXT OFF
30 |
31 | SET STATISTICS IO ON;
32 | GO
33 | SELECT *
34 | FROM [Application].[Cities]
35 | WHERE CityID IN (23629,334);
36 | GO
37 | SET STATISTICS IO OFF
38 |
39 |
40 | SET SHOWPLAN_TEXT ON;
41 | GO
42 | SELECT *
43 | FROM [Application].[Cities]
44 | WHERE CityID > 0;
45 | GO
46 | SET SHOWPLAN_TEXT OFF
47 |
48 | GO
49 |
50 | -----Nonclustered Indexes
51 |
52 |
53 | SELECT CONCAT(OBJECT_SCHEMA_NAME(i.object_id),'.',OBJECT_NAME(i.object_id)) AS object_name
54 | , CASE WHEN i.is_unique = 1 THEN 'UNIQUE ' ELSE '' END +
55 | i.TYPE_DESC AS index_type
56 | , i.name as index_name
57 | , user_seeks, user_scans, user_lookups,user_updates
58 | FROM sys.indexes AS i
59 | LEFT OUTER JOIN sys.dm_db_index_usage_stats AS s
60 | ON i.object_id = s.object_id
61 | AND i.index_id = s.index_id
62 | AND database_id = DB_ID()
63 | WHERE OBJECTPROPERTY(i.object_id , 'IsUserTable') = 1
64 | ORDER BY object_name, index_name;
65 | GO
66 |
67 | SET SHOWPLAN_TEXT ON;
68 | GO
69 | SELECT *
70 | FROM Application.Cities
71 | WHERE CityName = 'Nashville';
72 | GO
73 | SET SHOWPLAN_TEXT OFF
74 | GO
75 | CREATE INDEX CityName ON Application.Cities(CityName) ON USERDATA;
76 | GO
77 |
78 | SET SHOWPLAN_TEXT ON;
79 | GO
80 | SELECT *
81 | FROM Application.Cities
82 | WHERE CityName = 'Nashville';
83 | GO
84 | SET SHOWPLAN_TEXT OFF
85 | GO
86 |
87 |
88 | ------Determining Index Usefulness
89 |
90 | DBCC SHOW_STATISTICS('Application.Cities', 'CityName') WITH DENSITY_VECTOR;
91 | DBCC SHOW_STATISTICS('Application.Cities', 'CityName') WITH HISTOGRAM;
92 | GO
93 |
94 | --Used ISNULL as it is easier if the column can be null
95 | --value you translate to should be impossible for the column
96 | --ProductId is an identity with seed of 1 and increment of 1
97 | --so this should be safe (unless a dba does something weird)
98 | SELECT 1.0/ COUNT(DISTINCT ISNULL(CityName,'NotACity')) AS density,
99 | COUNT(DISTINCT ISNULL(CityName,'NotACity')) AS distinctRowCount,
100 | 1.0/ COUNT(*) AS uniqueDensity,
101 | COUNT(*) AS allRowCount
102 | FROM Application.Cities;
103 | GO
104 |
105 |
106 | USE tempDB;
107 | GO
108 | CREATE SCHEMA demo;
109 | GO
110 | CREATE TABLE demo.testIndex
111 | (
112 | testIndex int IDENTITY(1,1) CONSTRAINT PKtestIndex PRIMARY KEY,
113 | bitValue bit,
114 | filler char(2000) NOT NULL DEFAULT (REPLICATE('A',2000))
115 | );
116 | CREATE INDEX bitValue ON demo.testIndex(bitValue);
117 | GO
118 |
119 | SET NOCOUNT ON; --or you will get back 50100 1 row affected messages
120 | INSERT INTO demo.testIndex(bitValue)
121 | VALUES (0);
122 | GO 50000 --runs current batch 50000 times in Management Studio.
123 |
124 | INSERT INTO demo.testIndex(bitValue)
125 | VALUES (1);
126 | GO 100 --puts 100 rows into table with value 1
127 |
128 | SET SHOWPLAN_TEXT ON;
129 | GO
130 | SELECT *
131 | FROM demo.testIndex
132 | WHERE bitValue = 0;
133 | GO
134 | SET SHOWPLAN_TEXT OFF
135 | GO
136 |
137 | SET SHOWPLAN_TEXT ON;
138 | GO
139 | SELECT *
140 | FROM demo.testIndex
141 | WHERE bitValue = 1;
142 | GO
143 | SET SHOWPLAN_TEXT OFF
144 | GO
145 |
146 |
147 |
148 | UPDATE STATISTICS demo.testIndex;
149 | DBCC SHOW_STATISTICS('demo.testIndex', 'bitValue') WITH HISTOGRAM;
150 | GO
151 |
152 | CREATE INDEX bitValueOneOnly
153 | ON testIndex(bitValue) WHERE bitValue = 1;
154 |
155 | DBCC SHOW_STATISTICS('demo.testIndex', 'bitValueOneOnly') WITH HISTOGRAM;
156 | GO
157 |
158 | -----Indexing and Multiple Columns
159 |
160 | USE WideWorldImporters;
161 | GO
162 | SET SHOWPLAN_TEXT ON;
163 | GO
164 | SELECT *
165 | FROM Application.Cities
166 | WHERE CityName = 'Nashville'
167 | AND LatestRecordedPopulation = 601222;
168 | GO
169 | SET SHOWPLAN_TEXT OFF
170 | GO
171 |
172 | SELECT CityName, LatestRecordedPopulation, COUNT(*) AS [count]
173 | FROM Application.Cities
174 | GROUP BY CityName, LatestRecordedPopulation
175 | ORDER BY CityName, LatestRecordedPopulation;
176 | GO
177 |
178 | SELECT COUNT(DISTINCT CityName) as CityName,
179 | SUM(CASE WHEN CityName IS NULL THEN 1 ELSE 0 END) as NULLCityName,
180 | COUNT(DISTINCT LatestRecordedPopulation) as LatestRecordedPopulation,
181 | SUM(CASE WHEN LatestRecordedPopulation IS NULL THEN 1 ELSE 0 END)
182 | AS NULLLatestRecordedPopulation
183 | FROM Application.Cities;
184 | GO
185 |
186 | CREATE INDEX CityNameAndLastRecordedPopulation
187 | ON Application.Cities (CityName, LatestRecordedPopulation);
188 |
189 | SET SHOWPLAN_TEXT ON;
190 | GO
191 | SELECT *
192 | FROM Application.Cities
193 | WHERE CityName = 'Nashville'
194 | AND LatestRecordedPopulation = 601222;
195 | GO
196 | SET SHOWPLAN_TEXT OFF
197 | GO
198 |
199 | -------covering indexes
200 |
201 | SET SHOWPLAN_TEXT ON;
202 | GO
203 | SELECT CityName, LatestRecordedPopulation, LastEditedBy
204 | FROM Application.Cities;
205 | GO
206 | SET SHOWPLAN_TEXT OFF
207 | GO
208 |
209 | SET SHOWPLAN_TEXT ON;
210 | GO
211 | SELECT CityName, LatestRecordedPopulation, LastEditedBy
212 | FROM Application.Cities;
213 | GO
214 | SET SHOWPLAN_TEXT OFF
215 | GO
216 |
217 |
218 | DROP INDEX CityNameAndLastRecordedPopulation
219 | ON Application.Cities;
220 | GO
221 |
222 | CREATE INDEX CityNameAndLastRecordedPopulation
223 | ON Application.Cities (CityName, LatestRecordedPopulation)
224 | INCLUDE (LastEditedBy);
225 | GO
226 |
227 | SET SHOWPLAN_TEXT ON;
228 | GO
229 |
230 | SELECT CityName, LatestRecordedPopulation
231 | FROM Application.Cities;
232 | GO
233 |
234 | SET SHOWPLAN_TEXT OFF;
235 | GO
236 |
237 | ------Multiple Indexes
238 |
239 | SET SHOWPLAN_TEXT ON;
240 | GO
241 | SELECT CityName, StateProvinceID
242 | FROM Application.Cities
243 | WHERE CityName = 'Nashville'
244 | AND StateProvinceID = 44;
245 | GO
246 | SET SHOWPLAN_TEXT OFF
247 | GO
248 |
249 | -------Sort Order of Index Keys
250 |
251 | SET SHOWPLAN_TEXT ON;
252 | GO
253 | SELECT CityName, LatestRecordedPopulation
254 | FROM Application.Cities
255 | ORDER BY CityName ASC, LatestRecordedPopulation DESC;
256 | GO
257 | SET SHOWPLAN_TEXT OFF
258 | GO
259 |
260 | DROP INDEX CityNameAndLastRecordedPopulation
261 | ON Application.Cities;
262 |
263 | CREATE INDEX CityNameAndLastRecordedPopulation
264 | ON Application.Cities (CityName, LatestRecordedPopulation DESC)
265 | INCLUDE (LastEditedBy);
266 |
267 |
268 | ----Nonclustered Indexes on a Heap
269 | SELECT *
270 | INTO Application.HeapCities
271 | FROM Application.Cities;
272 | GO
273 |
274 | ALTER TABLE Application.HeapCities
275 | ADD CONSTRAINT PKHeapCities PRIMARY KEY NONCLUSTERED (CityID);
276 | GO
277 |
278 | CREATE INDEX CityName ON Application.HeapCities(CityName) ON USERDATA;
279 | GO
280 |
281 | SET SHOWPLAN_TEXT ON;
282 | GO
283 | SELECT *
284 | FROM Application.HeapCities
285 | WHERE CityID = 23629;
286 | GO
287 | SET SHOWPLAN_TEXT OFF
288 | GO
289 |
290 |
291 |
292 |
293 | ---Memory Optimized Indexes
294 | ------In-Memory OLTP Tables
295 | --------General Table Structure
296 |
297 | USE WideWorldImporters
298 | GO
299 |
300 |
301 | SET SHOWPLAN_TEXT ON;
302 | GO
303 | SELECT *
304 | FROM Warehouse.VehicleTemperatures
305 | GO
306 | SET SHOWPLAN_TEXT OFF
307 | GO
308 |
309 | SET SHOWPLAN_TEXT ON;
310 | GO
311 | SELECT *
312 | FROM Warehouse.VehicleTemperatures
313 | WHERE VehicleTemperatureID = 2332;
314 | GO
315 | SET SHOWPLAN_TEXT OFF
316 | GO
317 |
318 | SET SHOWPLAN_TEXT ON;
319 | GO
320 | SELECT *
321 | FROM Warehouse.VehicleTemperatures
322 | WHERE VehicleTemperatureID <> 0;
323 | GO
324 | SET SHOWPLAN_TEXT OFF
325 | GO
326 |
327 | SET STATISTICS TIME ON;
328 | GO
329 | SELECT *
330 | FROM Warehouse.VehicleTemperatures
331 | WHERE VehicleTemperatureID <> 0;
332 | GO
333 | SET STATISTICS TIME OFF;
334 | GO
335 |
336 | SET STATISTICS TIME ON;
337 | GO
338 | SELECT *
339 | FROM Warehouse.VehicleTemperatures WITH (INDEX = 0)
340 | WHERE VehicleTemperatureID <> 0;
341 | GO
342 | SET STATISTICS TIME OFF;
343 | GO
344 |
345 | ALTER TABLE Warehouse.VehicleTemperatures
346 | ADD INDEX RecordedWhen --33000 distinct values,
347 | HASH (RecordedWhen) WITH (BUCKET_COUNT = 64000) --values are in powers of 2
348 |
349 |
350 | SET SHOWPLAN_TEXT ON;
351 | GO
352 | SELECT *
353 | FROM Warehouse.VehicleTemperatures
354 | WHERE RecordedWhen = '2016-03-10 12:50:22.0000000';
355 | GO
356 | SET SHOWPLAN_TEXT OFF
357 | GO
358 |
359 | SET SHOWPLAN_TEXT ON;
360 | GO
361 | SELECT *
362 | FROM Warehouse.VehicleTemperatures
363 | WHERE RecordedWhen BETWEEN '2016-03-10 12:50:22.0000000' AND '2016-03-10 12:50:22.0000000';
364 | GO
365 | SET SHOWPLAN_TEXT OFF
366 | GO
367 |
368 | -------Indexed Views
369 |
370 | CREATE VIEW Warehouse.StockItemSalesTotals
371 | WITH SCHEMABINDING
372 | AS
373 | SELECT StockItems.StockItemName,
374 | --ISNULL because expression can't be nullable
375 | SUM(OrderLines.Quantity * ISNULL(OrderLines.UnitPrice,0)) AS TotalSalesAmount,
376 | COUNT_BIG(*) AS TotalSalesCount--must use COUNT_BIG for indexed view
377 | FROM Warehouse.StockItems
378 | JOIN Sales.OrderLines
379 | ON OrderLines.StockItemID = StockItems.StockItemID
380 | GROUP BY StockItems.StockItemName;
381 | GO
382 |
383 | SET SHOWPLAN_TEXT ON;
384 | GO
385 | SELECT *
386 | FROM Warehouse.StockItemSalesTotals;
387 | GO
388 | SET SHOWPLAN_TEXT OFF
389 | GO
390 |
391 | CREATE UNIQUE CLUSTERED INDEX XPKStockItemSalesTotals on
392 | Warehouse.StockItemSalesTotals(StockItemName);
393 |
394 | SET SHOWPLAN_TEXT ON;
395 | GO
396 | SELECT *
397 | FROM Warehouse.StockItemSalesTotals;
398 | GO
399 | SET SHOWPLAN_TEXT OFF
400 | GO
401 |
402 | SET SHOWPLAN_TEXT ON;
403 | GO
404 | SELECT StockItems.StockItemName,
405 | SUM(OrderLines.Quantity * ISNULL(OrderLines.UnitPrice,0)) / COUNT_BIG(*) AS AverageSaleAmount
406 | FROM Warehouse.StockItems
407 | JOIN Sales.OrderLines
408 | ON OrderLines.StockItemID = StockItems.StockItemID
409 | GROUP BY StockItems.StockItemName;
410 | GO
411 | SET SHOWPLAN_TEXT OFF
412 | GO
413 |
414 | ------Compression
415 |
416 | USE Tempdb
417 | GO
418 | CREATE TABLE dbo.TestCompression
419 | (
420 | TestCompressionId int,
421 | Value int
422 | )
423 | WITH (DATA_COMPRESSION = ROW) -- PAGE or NONE
424 | ALTER TABLE testCompression REBUILD WITH (DATA_COMPRESSION = PAGE);
425 |
426 | CREATE CLUSTERED INDEX Value
427 | ON testCompression (Value) WITH ( DATA_COMPRESSION = ROW );
428 |
429 | ALTER INDEX Value ON testCompression REBUILD WITH ( DATA_COMPRESSION = PAGE );
430 |
431 | --------Partitioning
432 | USE WideWorldImporters
433 | GO
434 |
435 | SELECT YEAR(OrderDate), COUNT(*)
436 | FROM Sales.Orders
437 | GROUP BY YEAR(OrderDate)
438 | ORDER BY YEAR(OrderDate);
439 |
440 | USE Tempdb;
441 | GO
442 | --Note that the PARTITON FUNCTION is not a schema owned object
443 | CREATE PARTITION FUNCTION PartitionFunction$Dates (date)
444 | AS RANGE LEFT FOR VALUES ('20140101','20150101');
445 | --set based on recent version of
446 | --WideWorldImporters.Sales.Orders table to show
447 | --partition utilization
448 | GO
449 | CREATE PARTITION SCHEME PartitonScheme$dates
450 | AS PARTITION PartitionFunction$dates ALL to ( [PRIMARY] );
451 | GO
452 |
453 | CREATE TABLE dbo.Orders
454 | (
455 | OrderId int,
456 | CustomerId int,
457 | OrderDate date,
458 | CONSTRAINT PKOrder PRIMARY KEY NONCLUSTERED (OrderId) ON [Primary],
459 | CONSTRAINT AKOrder UNIQUE CLUSTERED (OrderId, OrderDate)
460 | ) ON PartitonScheme$dates (OrderDate);
461 | GO
462 |
463 | INSERT INTO dbo.Orders (OrderId, CustomerId, OrderDate)
464 | SELECT OrderId, CustomerId, OrderDate
465 | FROM WideWorldImporters.Sales.Orders;
466 | GO
467 |
468 | SELECT *, $partition.PartitionFunction$dates(orderDate) as partiton
469 | FROM dbo.Orders;
470 | GO
471 |
472 | SELECT partitions.partition_number, partitions.index_id,
473 | partitions.rows, indexes.name, indexes.type_desc
474 | FROM sys.partitions as partitions
475 | JOIN sys.indexes as indexes
476 | on indexes.object_id = partitions.object_id
477 | and indexes.index_id = partitions.index_id
478 | WHERE partitions.object_id = object_id('dbo.Orders');
479 | GO
480 |
481 |
482 | -----Index Dynamic Management View Queries
483 | ---Missing Indexes
484 |
485 | SELECT ddmid.statement AS object_name, ddmid.equality_columns, ddmid.inequality_columns,
486 | ddmid.included_columns, ddmigs.user_seeks, ddmigs.user_scans,
487 | ddmigs.last_user_seek, ddmigs.last_user_scan, ddmigs.avg_total_user_cost,
488 | ddmigs.avg_user_impact, ddmigs.unique_compiles
489 | FROM sys.dm_db_missing_index_groups AS ddmig
490 | JOIN sys.dm_db_missing_index_group_stats AS ddmigs
491 | ON ddmig.index_group_handle = ddmigs.group_handle
492 | JOIN sys.dm_db_missing_index_details AS ddmid
493 | ON ddmid.index_handle = ddmig.index_handle
494 | ORDER BY ((user_seeks + user_scans) * avg_total_user_cost * (avg_user_impact * 0.01)) DESC;
495 | GO
496 |
497 | ----On-Disk Index Utilization Statistics
498 | SELECT OBJECT_SCHEMA_NAME(indexes.object_id) + '.' +
499 | OBJECT_NAME(indexes.object_id) as objectName,
500 | indexes.name,
501 | case when is_unique = 1 then 'UNIQUE '
502 | else '' end + indexes.type_desc as index_type,
503 | ddius.user_seeks, ddius.user_scans, ddius.user_lookups,
504 | ddius.user_updates, last_user_lookup, last_user_scan, last_user_seek,last_user_update
505 | FROM sys.indexes
506 | LEFT OUTER JOIN sys.dm_db_index_usage_stats ddius
507 | ON indexes.object_id = ddius.object_id
508 | AND indexes.index_id = ddius.index_id
509 | AND ddius.database_id = DB_ID()
510 | ORDER BY ddius.user_seeks + ddius.user_scans + ddius.user_lookups DESC;
511 | GO
512 |
513 | ----Fragmentation
514 | SELECT s.[name] AS SchemaName,
515 | o.[name] AS TableName,
516 | i.[name] AS IndexName,
517 | f.[avg_fragmentation_in_percent] AS FragPercent,
518 | f.fragment_count ,
519 | f.forwarded_record_count --heap only
520 | FROM sys.dm_db_index_physical_stats(DB_ID(), NULL, NULL, NULL, DEFAULT) f
521 | JOIN sys.indexes i
522 | ON f.[object_id] = i.[object_id] AND f.[index_id] = i.[index_id]
523 | JOIN sys.objects o
524 | ON i.[object_id] = o.[object_id]
525 | JOIN sys.schemas s
526 | ON o.[schema_id] = s.[schema_id]
527 | WHERE o.[is_ms_shipped] = 0
528 | AND i.[is_disabled] = 0; -- skip disabled indexes
529 | GO
530 |
531 | -----In-Memory OLTP Index Stats
532 | SELECT OBJECT_SCHEMA_NAME(object_id) + '.' +
533 | OBJECT_NAME(object_id) AS objectName,
534 | memory_allocated_for_table_kb,memory_used_by_table_kb,
535 | memory_allocated_for_indexes_kb,memory_used_by_indexes_kb
536 | FROM sys.dm_db_xtp_table_memory_stats;
537 | SELECT OBJECT_SCHEMA_NAME(ddxis.object_id) + '.' +
538 | OBJECT_NAME(ddxis.object_id) AS objectName,
539 | ISNULL(indexes.name,'BaseTable') AS indexName,
540 | scans_started, rows_returned, rows_touched,
541 | rows_expiring, rows_expired,
542 | rows_expired_removed, phantom_scans_started --and several other phantom columns
543 | FROM sys.dm_db_xtp_index_stats AS ddxis
544 | JOIN sys.indexes
545 | ON indexes.index_id = ddxis.index_id
546 | AND indexes.object_id = ddxis.object_id
547 | GO
548 | SELECT OBJECT_SCHEMA_NAME(ddxhis.object_id) + '.' +
549 | OBJECT_NAME(ddxhis.object_id) AS objectName,
550 | ISNULL(indexes.name,'BaseTable') AS indexName,
551 | ddxhis.total_bucket_count, ddxhis.empty_bucket_count,
552 | ddxhis.avg_chain_length, ddxhis.max_chain_length
553 | FROM sys.dm_db_xtp_hash_index_stats ddxhis
554 | JOIN sys.indexes
555 | ON indexes.index_id = ddxhis.index_id
556 | AND indexes.object_id = ddxhis.object_id
557 | GO
--------------------------------------------------------------------------------
/Code/Chapter 13.sql:
--------------------------------------------------------------------------------
1 | --Choosing the Engine for Your Needs
2 | ---Ad Hoc SQL
3 | ----Advantages
4 | -----Runtime Control over Queries
5 | CREATE SCHEMA Sales;
6 | GO
7 | CREATE TABLE Sales.Contact
8 | (
9 | ContactId int CONSTRAINT PKContact PRIMARY KEY,
10 | FirstName varchar(30),
11 | LastName varchar(30),
12 | LompanyName varchar(100),
13 | SalesLevelId int, --real table would implement as a foreign key
14 | ContactNotes varchar(max),
15 | CONSTRAINT AKContact UNIQUE (FirstName, LastName, CompanyName)
16 | );
17 | --a few rows to show some output from queries
18 | INSERT INTO Sales.Contact
19 | (ContactId, FirstName, Lastname, CompanyName, SaleslevelId, ContactNotes)
20 | VALUES( 1,'Drue','Karry','SeeBeeEss',1,
21 | REPLICATE ('Blah...',10) + 'Called and discussed new ideas'),
22 | ( 2,'Jon','Rettre','Daughter Inc',2,
23 | REPLICATE ('Yada...',10) + 'Called, but he had passed on');
24 | GO
25 |
26 |
27 | SELECT ContactId, FirstName, LastName, CompanyName,
28 | RIGHT(ContactNotes,30) as NotesEnd
29 | FROM Sales.Contact;
30 | GO
31 |
32 | SELECT ContactId, FirstName, LastName, CompanyName
33 | FROM Sales.Contact;
34 | GO
35 |
36 | CREATE TABLE Sales.Purchase
37 | (
38 | PurchaseId int CONSTRAINT PKPurchase PRIMARY KEY,
39 | Amount numeric(10,2),
40 | PurchaseDate date,
41 | ContactId int
42 | CONSTRAINT FKContact$hasPurchasesIn$Sales_Purchase
43 | REFERENCES Sales.Contact(ContactId)
44 | );
45 | GO
46 | INSERT INTO Sales.Purchase(PurchaseId, Amount, PurchaseDate, ContactId)
47 | VALUES (1,100.00,'2016-05-12',1),(2,200.00,'2016-05-10',1),
48 | (3,100.00,'2016-05-12',2),(4,300.00,'2016-05-12',1),
49 | (5,100.00,'2016-04-11',1),(6,5500.00,'2016-05-14',2),
50 | (7,100.00,'2016-04-01',1),(8,1020.00,'2016-06-03',2);
51 | GO
52 |
53 |
54 | SELECT Contact.ContactId, Contact.FirstName, Contact.LastName
55 | ,Sales.YearToDateSales, Sales.LastSaleDate
56 | FROM Sales.Contact as Contact
57 | LEFT OUTER JOIN
58 | (SELECT ContactId,
59 | SUM(Amount) AS YearToDateSales,
60 | MAX(PurchaseDate) AS LastSaleDate
61 | FROM Sales.Purchase
62 | WHERE PurchaseDate >= --the first day of the current year
63 | DATEADD(day, 0, DATEDIFF(day, 0, SYSDATETIME() )
64 | - DATEPART(dayofyear,SYSDATETIME() ) + 1)
65 | GROUP by ContactId) AS sales
66 | ON Contact.ContactId = Sales.ContactId
67 | WHERE Contact.LastName like 'Rett%';
68 | GO
69 |
70 |
71 | SELECT Contact.ContactId, Contact.FirstName, Contact.LastName
72 | --,Sales.YearToDateSales, Sales.LastSaleDate
73 | FROM Sales.Contact as Contact
74 | --LEFT OUTER JOIN
75 | -- (SELECT ContactId,
76 | -- SUM(Amount) AS YearToDateSales,
77 | -- MAX(PurchaseDate) AS LastSaleDate
78 | -- FROM Sales.Purchase
79 | -- WHERE PurchaseDate >= --the first day of the current year
80 | -- DATEADD(day, 0, DATEDIFF(day, 0, SYSDATETIME() )
81 | -- - DATEPART(dayofyear,SYSDATETIME() ) + 1)
82 | -- GROUP by ContactId) AS sales
83 | -- ON Contact.ContactId = Sales.ContactId
84 | WHERE Contact.LastName like 'Karr%';
85 |
86 | UPDATE Sales.Contact
87 | SET FirstName = 'Drew',
88 | LastName = 'Carey',
89 | SalesLevelId = 1, --no change
90 | CompanyName = 'CBS',
91 | ContactNotes = 'Blah...Blah...Blah...Blah...Blah...Blah...Blah...Blah...Blah...'
92 | + 'Blah...Called and discussed new ideas' --no change
93 | WHERE ContactId = 1;
94 | GO
95 |
96 | UPDATE Sales.Contact
97 | SET FirstName = 'John',
98 | LastName = 'Ritter'
99 | WHERE ContactId = 2;
100 | GO
101 |
102 | SELECT FirstName, LastName, CompanyName
103 | FROM Sales.Contact
104 | WHERE FirstName LIKE 'J%'
105 | AND LastName LIKE 'R%';
106 | GO
107 |
108 | SELECT FirstName, LastName, CompanyName
109 | FROM Sales.Contact
110 | WHERE FirstName LIKE '%'
111 | AND LastName LIKE 'Carey%';
112 | GO
113 |
114 |
115 | SELECT FirstName, LastName, CompanyName
116 | FROM Sales.Contact
117 | WHERE LastName LIKE 'Carey%';
118 | GO
119 |
120 | IF @FirstNameValue <> '%'
121 | SELECT FirstName, LastName, CompanyName
122 | FROM Sales.Contact
123 | WHERE FirstName LIKE @FirstNameLike
124 | AND LastName LIKE @LastNameLike;
125 | ELSE
126 | SELECT FirstName, LastName, CompanyName
127 | FROM Sales.Contact
128 | WHERE FirstName LIKE @FirstNameLike;
129 | GO
130 |
131 | ---Flexibility over Shared Plans and Parameterization
132 | USE WideWorldImporters;
133 | GO
134 | SET SHOWPLAN_TEXT ON
135 | GO
136 | SELECT People.FullName, Orders.OrderDate
137 | FROM Sales.Orders
138 | JOIN Application.People
139 | ON Orders.ContactPersonID = People.PersonID
140 | WHERE People.FullName = N'Bala Dixit';
141 | GO
142 | SET SHOWPLAN_TEXT OFF
143 | GO
144 |
145 | SET SHOWPLAN_TEXT ON
146 | GO
147 | SELECT People.FullName, Orders.OrderDate
148 | FROM Sales.Orders
149 | JOIN Application.People
150 | on Orders.ContactPersonID = People.PersonID
151 | WHERE People.FullName = N'Bala Dixit';
152 | GO
153 | SET SHOWPLAN_TEXT OFF
154 | GO
155 |
156 |
157 | SELECT *
158 | FROM (SELECT qs.execution_count,
159 | SUBSTRING(st.text, (qs.statement_start_offset / 2) + 1,
160 | ((CASE qs.statement_end_offset
161 | WHEN -1 THEN DATALENGTH(st.text)
162 | ELSE qs.statement_end_offset
163 | END - qs.statement_start_offset) / 2) + 1) AS statement_text
164 | FROM sys.dm_exec_query_stats AS qs
165 | CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) AS st
166 | ) AS queryStats
167 | WHERE queryStats.statement_text LIKE 'SELECT People.FullName, Orders.OrderDate%';
168 | GO
169 |
170 | SET SHOWPLAN_TEXT ON
171 | GO
172 | SELECT People.FullName
173 | FROM Application.People
174 | WHERE People.FullName = N'Bala Dixit';
175 | GO
176 | SET SHOWPLAN_TEXT OFF
177 | GO
178 |
179 |
180 | SET SHOWPLAN_TEXT ON
181 | GO
182 |
183 | SELECT address.AddressLine1, address.AddressLine2,
184 | address.City, state.StateProvinceCode, address.PostalCode
185 | FROM Person.Address AS address
186 | JOIN Person.StateProvince AS state
187 | ON address.StateProvinceID = state.StateProvinceID
188 | WHERE address.AddressLine1 ='1, rue Pierre-Demoulin';
189 | SET SHOWPLAN_TEXT OFF
190 | GO
191 |
192 |
193 | ALTER DATABASE WideWorldImporters
194 | SET PARAMETERIZATION FORCED;
195 |
196 | SET SHOWPLAN_TEXT ON
197 | GO
198 | SELECT address.AddressLine1, address.AddressLine2,
199 | address.City, state.StateProvinceCode, address.PostalCode
200 | FROM Person.Address AS address
201 | JOIN Person.StateProvince as state
202 | ON address.StateProvinceID = state.StateProvinceID
203 | WHERE address.AddressLine1 like '1, rue Pierre-Demoulin';
204 | SET SHOWPLAN_TEXT OFF
205 | GO
206 |
207 | DECLARE @FullName nvarchar(60) = N'Bala Dixit',
208 | @Query nvarchar(500),
209 | @Parameters nvarchar(500)
210 |
211 | SET @Query= N'SELECT People.FullName, Orders.OrderDate
212 | FROM Sales.Orders
213 | JOIN Application.People
214 | on Orders.ContactPersonID = People.PersonID
215 | WHERE People.FullName LIKE @FullName';;
216 | SET @Parameters = N'@FullName nvarchar(60)';
217 |
218 | EXECUTE sp_executesql @Query, @Parameters, @FullName = @FullName;
219 | GO
220 |
221 |
222 | DECLARE @Query nvarchar(500),
223 | @Parameters nvarchar(500),
224 | @Handle int
225 | SET @Query= N'SELECT People.FullName, Orders.OrderDate
226 | FROM Sales.Orders
227 | JOIN Application.People
228 | ON Orders.ContactPersonID = People.PersonID
229 | WHERE People.FullName LIKE @FullName';
230 | SET @Parameters = N'@FullName nvarchar(60)';
231 | GO
232 |
233 | EXECUTE sp_prepare @Handle output, @Parameters, @Query;
234 | SELECT @handle;
235 |
236 | DECLARE @FullName nvarchar(60) = N'Bala Dixit';
237 | EXECUTE sp_execute 1, @FullName;
238 | SET @FullName = N'Bala%';
239 | EXECUTE sp_execute 1, @FullName;
240 |
241 |
242 |
243 | --Security Issues
244 | ----SQL Injection
245 | DECLARE @value varchar(30) = 'O''Malley';
246 | SELECT 'SELECT '''+ @value + '''';
247 | EXECUTE ('SELECT '''+ @value + '''');
248 |
249 | DECLARE @value varchar(30) = 'O''Malley', @query nvarchar(300);
250 | SELECT @query = 'SELECT ' + QUOTENAME(@value,'''');
251 | SELECT @query;
252 | EXECUTE (@query );
253 | GO
254 |
255 |
256 | DECLARE @value varchar(30) = 'O''; SELECT ''badness',
257 | @query nvarchar(300);
258 | SELECT @query = 'SELECT ' + QUOTENAME(@value,'''');
259 | SELECT @query;
260 | EXECUTE (@query );
261 | GO
262 |
263 |
264 | DECLARE @value varchar(30) = 'O''; SELECT ''badness',
265 | @query nvarchar(300),
266 | @parameters nvarchar(200) = N'@value varchar(30)';
267 | SELECT @query = 'SELECT ' + QUOTENAME(@value,'''');
268 | SELECT @query;
269 | EXECUTE sp_executesql @Query, @Parameters, @value = @value;
270 | GO
271 |
272 | CREATE PROCEDURE Sales.Orders$Select
273 | (
274 | @FullNameLike nvarchar(100) = '%',
275 | @OrderDateRangeStart date = '1900-01-01',
276 | @OrderDateRangeEnd date = '9999-12-31'
277 | ) AS
278 | BEGIN
279 | SELECT People.FullName, Orders.OrderDate
280 | FROM Sales.Orders
281 | JOIN Application.People
282 | ON Orders.ContactPersonID = People.PersonID
283 | WHERE People.FullName LIKE @FullNameLike
284 | --Inclusive since using Date type
285 | AND OrderDate BETWEEN @OrderDateRangeStart
286 | AND @OrderDateRangeEnd
287 | END;
288 | GO
289 | EXECUTE Sales.Orders$Select @FullNameLike = 'Bala Dixit',
290 | @OrderDateRangeStart = '2016-01-01',
291 | @OrderDateRangeEnd = '2016-12-31';
292 | GO
293 |
294 | ---Advantages
295 | -----Encapsulation
296 | --pseudocode:
297 | CREATE PROCEDURE Sales.Orders$Select
298 | ...
299 |
300 | EXECUTE Sales.Orders$Select @FullNameLike = 'Bala Dixit',
301 | @OrderDateRangeStart = '2016-01-01',
302 | @OrderDateRangeEnd = '2016-12-31';
303 | GO
304 | EXECUTE sp_describe_first_result_set
305 | N'Sales.Orders$Select;'
306 | GO
307 |
308 | EXECUTE sp_describe_first_result_set
309 | N'Sales.Orders$Select @FullNameLike = ''Bala Dixit'';'
310 | GO
311 |
312 | CREATE PROCEDURE dbo.Test (@Value int = 1)
313 | AS
314 | IF @value = 1
315 | SELECT 'FRED' as Name;
316 | ELSE
317 | SELECT 200 as Name;
318 | GO
319 |
320 | EXECUTE sp_describe_first_result_set N'dbo.Test'
321 |
322 | ---Dynamic Procedures
323 |
324 | ALTER PROCEDURE Sales.Orders$Select
325 | (
326 | @FullNameLike nvarchar(100) = '%',
327 | @OrderDateRangeStart date = '1900-01-01',
328 | @OrderDateRangeEnd date = '9999-12-31'
329 | ) AS
330 | BEGIN
331 | DECLARE @query varchar(max) =
332 | CONCAT('
333 | SELECT People.FullName, Orders.OrderDate
334 | FROM Sales.Orders
335 | JOIN Application.People
336 | ON Orders.ContactPersonID = People.PersonID
337 | WHERE OrderDate BETWEEN ''', @OrderDateRangeStart, '''
338 | AND ''', @OrderDateRangeEnd,'''
339 | AND People.FullName LIKE ''', @FullNameLike, '''' );
340 | SELECT @query; --for testing
341 | EXECUTE (@query);
342 | END;
343 | GO
344 | EXECUTE Sales.Orders$Select @FullNameLike = '~;''select name from sysusers--',
345 | @OrderDateRangeStart = '2016-01-01';
346 | GO
347 |
348 | ALTER PROCEDURE Sales.Orders$Select
349 | (
350 | @FullNameLike nvarchar(100) = '%',
351 | @OrderDateRangeStart date = '1900-01-01',
352 | @OrderDateRangeEnd date = '9999-12-31'
353 | ) AS
354 | BEGIN
355 | DECLARE @query varchar(max) =
356 | CONCAT('
357 | SELECT People.FullName, Orders.OrderDate
358 | FROM Sales.Orders
359 | JOIN Application.People
360 | ON Orders.ContactPersonID = People.PersonID
361 | WHERE People.FullName LIKE ', QUOTENAME(@FullNameLike,''''), '
362 | AND OrderDate BETWEEN ', QUOTENAME(@OrderDateRangeStart,''''), '
363 | AND ', QUOTENAME(@OrderDateRangeEnd,''''));
364 | SELECT @query; --for testing
365 | EXECUTE (@query);
366 | END;
367 | GO
368 |
369 | ALTER PROCEDURE Sales.Orders$Select
370 | (
371 | @FullNameLike nvarchar(100) = '%',
372 | @OrderDateRangeStart date = '1900-01-01',
373 | @OrderDateRangeEnd date = '9999-12-31'
374 | ) AS
375 | BEGIN
376 | DECLARE @query varchar(max) =
377 | CONCAT('
378 | SELECT People.FullName, Orders.OrderDate
379 | FROM Sales.Orders
380 | JOIN Application.People
381 | ON Orders.ContactPersonID = People.PersonID
382 | WHERE 1=1
383 | ',
384 | --ignore @FullNameLike parameter when it is set to all
385 | CASE WHEN @FullNameLike <> '%' THEN
386 | CONCAT(' AND People.FullName LIKE ', QUOTENAME(@FullNameLike,''''))
387 | ELSE '' END,
388 | --ignore @date parameters when it is set to all
389 |
390 |
391 | CASE WHEN @OrderDateRangeStart <> '1900-01-01' OR
392 | @OrderDateRangeEnd <> '9999-12-31'
393 | THEN
394 | CONCAT('AND OrderDate BETWEEN ', QUOTENAME(@OrderDateRangeStart,''''), '
395 | AND ', QUOTENAME(@OrderDateRangeEnd,''''))
396 | ELSE '' END);
397 | SELECT @query; --for testing
398 | EXECUTE (@query);
399 | END;
400 | GO
401 |
402 | ---Security
403 | CREATE PROCEDURE dbo.TestChaining
404 | AS
405 | EXECUTE ('SELECT CustomerID, StoreID, AccountNumber
406 | FROM Sales.Customer');
407 | GO
408 | GO
409 |
410 | GRANT EXECUTE ON testChaining TO fred;
411 | GO
412 |
413 | EXECUTE AS USER = 'Fred';
414 | EXECUTE dbo.testChaining;
415 | REVERT;
416 | GO
417 |
418 | ALTER PROCEDURE dbo.testChaining
419 | WITH EXECUTE AS SELF
420 | AS
421 | EXECUTE ('SELECT CustomerID, StoreId, AccountNumber
422 | FROM Sales.Customer');
423 | GO
424 |
425 | CREATE PROCEDURE dbo.YouCanDoAnything_ButDontDoThis
426 | (
427 | @query nvarchar(4000)
428 | )
429 | WITH EXECUTE AS SELF
430 | AS
431 | EXECUTE (@query);
432 | GO
433 |
434 | ---Performance
435 | -------Ability to use the In-Memory Engine to its Fullest
436 | USE WideWorldImporters;
437 | GO
438 | CREATE PROCEDURE Warehouse.VehicleTemperatures$Select
439 | (
440 | @TemperatureLowRange decimal(10,2) = -99999999.99,
441 | @TemperatureHighRange decimal(10,2) = 99999999.99
442 | )
443 | WITH SCHEMABINDING, NATIVE_COMPILATION AS
444 | BEGIN ATOMIC WITH (TRANSACTION ISOLATION LEVEL = SNAPSHOT, LANGUAGE = N'us_english')
445 | SELECT VehicleTemperatureID, VehicleRegistration,
446 | RecordedWhen, Temperature
447 | FROM Warehouse.VehicleTemperatures
448 | WHERE Temperature BETWEEN @TemperatureLowRange AND @TemperatureHighRange
449 | ORDER BY RecordedWhen DESC; --Most Recent First
450 | END;
451 | GO
452 |
453 | EXECUTE Warehouse.VehicleTemperatures$Select ;
454 | EXECUTE Warehouse.VehicleTemperatures$Select @TemperatureLowRange = 4;
455 | EXECUTE Warehouse.VehicleTemperatures$Select @TemperatureLowRange = 4.1,
456 | @TemperatureHighRange = 4.1;
457 | GO
458 |
459 |
460 | CREATE PROCEDURE Warehouse.VehicleTemperatures$FixTemperature
461 | (
462 | @VehicleTemperatureID int,
463 | @Temperature decimal(10,2)
464 | )
465 | WITH SCHEMABINDING, NATIVE_COMPILATION AS
466 | --Simulating a procedure you might write to fix a temperature that was found to be
467 | --outside of reasonability
468 | BEGIN ATOMIC WITH (TRANSACTION ISOLATION LEVEL = SNAPSHOT, LANGUAGE = N'us_english')
469 | BEGIN TRY
470 | --Update the temperature
471 | UPDATE Warehouse.VehicleTemperatures
472 | SET Temperature = @Temperature
473 | WHERE VehicleTemperatureID = @VehicleTemperatureID;
474 |
475 | --give the ability to crash the procedure for demo
476 | --Note, actually doing 1/0 is stopped by the compiler
477 | DECLARE @CauseFailure int
478 | SET @CauseFailure = 1/@Temperature;
479 |
480 | --return data if not a fail
481 | SELECT 'Success' AS Status, VehicleTemperatureID,
482 | Temperature
483 | FROM Warehouse.VehicleTemperatures
484 | WHERE VehicleTemperatureID = @VehicleTemperatureID;
485 | END TRY
486 | BEGIN CATCH
487 | --return data for the fail
488 | SELECT 'Failure' AS Status, VehicleTemperatureID,
489 | Temperature
490 | FROM Warehouse.VehicleTemperatures
491 | WHERE VehicleTemperatureID = @VehicleTemperatureID;
492 |
493 | THROW; --This will cause the batch to stop, and will cause this
494 | --transaction to not be committed. Cannot use ROLLBACK
495 | --does not necessarily end the transaction, even if it ends
496 | --the batch.
497 | END CATCH
498 | END;
499 | GO
500 |
501 | --Show original value of temperature for a given row
502 | SELECT Temperature
503 | FROM Warehouse.VehicleTemperatures
504 | WHERE VehicleTemperatureID = 65994;
505 | GO
506 |
507 | EXECUTE Warehouse.VehicleTemperatures$FixTemperature
508 | @VehicleTemperatureId = 65994,
509 | @Temperature = 4.2;
510 | GO
511 |
512 | EXECUTE Warehouse.VehicleTemperatures$FixTemperature
513 | @VehicleTemperatureId = 65994,
514 | @Temperature = 0;
515 | GO
516 |
517 | EXECUTE Warehouse.VehicleTemperatures$FixTemperature
518 | @VehicleTemperatureId = 65994,
519 | @Temperature = 0,
520 | @ThrowErrorFlag = 0;
521 | GO
522 |
523 | SELECT @@TRANCOUNT AS TranStart;
524 | BEGIN TRANSACTION
525 | EXECUTE Warehouse.VehicleTemperatures$FixTemperature
526 | @VehicleTemperatureId = 65994,
527 | @Temperature = 0,
528 | @ThrowErrorFlag = 1;
529 | GO
530 | SELECT @@TRANCOUNT AS TranEnd;
531 | GO
532 | SELECT Temperature
533 | FROM Warehouse.VehicleTemperatures
534 | WHERE VehicleTemperatureID = 65994;
535 | GO
536 |
537 |
538 |
539 | ---Difficulty Affecting Only Certain Columns in an Operation
540 | CREATE PROCEDURE Sales.Contact$Update
541 | (
542 | @ContactId int,
543 | @FirstName varchar(30),
544 | @LastName varchar(30),
545 | @CompanyName varchar(100),
546 | @SalesLevelId int,
547 | @ContactNotes varchar(max)
548 | )
549 | AS
550 | DECLARE @entryTrancount int = @@trancount;
551 |
552 | BEGIN TRY
553 | UPDATE Sales.Contact
554 | SET FirstName = @FirstName,
555 | LastName = @LastName,
556 | CompanyName = @CompanyName,
557 | SalesLevelId = @SalesLevelId,
558 | ContactNotes = @ContactNotes
559 | WHERE ContactId = @ContactId;
560 | END TRY
561 | BEGIN CATCH
562 | IF @@trancount > 0
563 | ROLLBACK TRANSACTION;
564 |
565 | DECLARE @ERRORmessage nvarchar(4000)
566 | SET @ERRORmessage = 'Error occurred in procedure ''' +
567 | OBJECT_NAME(@@procid) + ''', Original Message: '''
568 | + ERROR_MESSAGE() + '''';
569 | THROW 50000,@ERRORmessage,1;
570 | END CATCH;
571 | GO
572 |
573 | ALTER PROCEDURE Sales.Contact$update
574 | (
575 | @ContactId int,
576 | @FirstName varchar(30),
577 | @LastName varchar(30),
578 | @CompanyName varchar(100),
579 | @SalesLevelId int,
580 | @ContactNotes varchar(max)
581 | )
582 | WITH EXECUTE AS SELF
583 | AS
584 | DECLARE @entryTrancount int = @@trancount;
585 |
586 | BEGIN TRY
587 | --declare variable to use to tell whether to include the sales level
588 | DECLARE @salesOrderIdChangedFlag bit =
589 | CASE WHEN (SELECT SalesLevelId
590 | FROM Sales.Contact
591 | WHERE ContactId = @ContactId) =
592 | @SalesLevelId
593 | THEN 0 ELSE 1 END;
594 |
595 | DECLARE @query nvarchar(max);
596 | SET @query = '
597 | UPDATE Sales.Contact
598 | SET FirstName = ' + QUOTENAME (@FirstName,'''') + ',
599 | LastName = ' + QUOTENAME(@LastName,'''') + ',
600 | CompanyName = ' + QUOTENAME(@CompanyName, '''') + ',
601 | '+ CASE WHEN @salesOrderIdChangedFlag = 1 THEN
602 | 'SalesLevelId = ' + QUOTENAME(@SalesLevelId, '''') + ',
603 | ' else '' END + ',
604 | ContactNotes = ' + QUOTENAME(@ContactNotes,'''') + '
605 |
606 | WHERE ContactId = ' + CAST(@ContactId AS varchar(10)) ;
607 | EXECUTE (@query);
608 | END TRY
609 | BEGIN CATCH
610 | IF @@TRANCOUNT > 0
611 | ROLLBACK TRANSACTION;
612 |
613 | DECLARE @ERRORmessage nvarchar(4000)
614 | SET @ERRORmessage = 'Error occurred in procedure ''' +
615 | OBJECT_NAME(@@procid) + ''', Original Message: '''
616 | + ERROR_MESSAGE() + '''';
617 | THROW 50000,@ERRORmessage,1;
618 | END CATCH;
619 | GO
620 |
621 | CREATE TRIGGER Sales.Contact$insteadOfUpdate
622 | ON Sales.Contact
623 | INSTEAD OF UPDATE
624 | AS
625 | BEGIN
626 | SET NOCOUNT ON;
627 | SET ROWCOUNT 0; --in case the client has modified the rowcount
628 | --use inserted for insert or update trigger, deleted for update or delete trigger
629 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
630 | --that is equal to number of merged rows, not rows being checked in trigger
631 | DECLARE @msg varchar(2000), --used to hold the error message
632 | --use inserted for insert or update trigger, deleted for update or delete trigger
633 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
634 | --that is equal to number of merged rows, not rows being checked in trigger
635 | @rowsAffected int = (SELECT COUNT(*) FROM inserted);
636 | -- @rowsAffected int = (SELECT COUNT(*) FROM deleted);
637 |
638 | --no need to continue on if no rows affected
639 | IF @rowsAffected = 0 RETURN;
640 |
641 | BEGIN TRY
642 | --[validation blocks]
643 | --[modification blocks]
644 | --
645 |
646 | UPDATE Contact
647 | SET FirstName = inserted.FirstName,
648 | LastName = inserted.LastName,
649 | CompanyName = inserted.CompanyName,
650 | PersonalNotes = inserted.PersonalNotes,
651 | ContactNotes = inserted.ContactNotes
652 | FROM Sales.Ccontact AS Contact
653 | JOIN inserted
654 | ON inserted.ContactId = Contact.ContactId
655 |
656 |
657 | IF UPDATE(SalesLevelId) --this column requires heavy validation
658 | --only want to update if necessary
659 | UPDATE Contact
660 | SET SalesLevelId = inserted.SalesLevelId
661 | FROM Sales.Contact
662 | JOIN inserted
663 | ON inserted.ContactId = Contact.ContactId
664 |
665 | --this correlated subquery checks for rows that have changed
666 | WHERE EXISTS (SELECT *
667 | FROM deleted
668 | WHERE deleted.ContactId =
669 | inserted.ContactId
670 | AND deleted.SalesLevelId <>
671 | inserted.SalesLevelId)
672 | END TRY
673 | BEGIN CATCH
674 | IF @@trancount > 0
675 | ROLLBACK TRANSACTION;
676 |
677 | THROW;
678 |
679 | END CATCH
680 | END;
681 | GO
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/LoadDimProcedure.dtsx:
--------------------------------------------------------------------------------
1 |
2 |
17 | 8
19 |
20 |
25 |
26 |
28 |
29 |
30 |
35 |
36 |
44 |
45 |
53 |
61 |
69 |
77 |
86 |
87 |
88 |
89 |
90 |
91 |
92 |
93 |
102 |
103 |
104 |
107 |
108 |
116 |
117 | 0
121 | [dim].[HCPCSProcedure]
125 |
129 |
134 | 1252
138 | false
142 | 3
147 | false
151 | false
155 | TABLOCK,CHECK_CONSTRAINTS
159 | 2147483647
163 |
164 |
165 |
171 |
172 |
173 |
179 |
180 |
188 |
196 |
204 |
205 |
207 |
211 |
217 |
223 |
229 |
230 |
231 |
232 |
233 |
255 |
256 |
257 |
266 |
267 | false
271 |
275 |
276 |
277 |
282 |
283 |
284 |
433 |
460 |
461 |
462 |
463 |
464 |
469 |
470 |
471 |
472 |
473 |
474 |
475 |
476 |
477 |
478 |
480 |
481 |
483 |
484 |
486 |
490 |
491 |
492 |
493 |
495 |
496 |
498 |
502 |
506 |
509 |
510 |
515 |
516 |
518 |
520 |
521 |
522 |
523 |
524 |
525 |
526 |
527 |
528 |
529 |
530 |
531 |
533 |
534 |
535 | DataSourceViewID
536 |
537 |
538 | TableInfoObjectType
539 | Table
541 |
542 |
543 |
544 | ]]>
545 |
--------------------------------------------------------------------------------
/Code/Chapter 14/HealthcareLoad/HealthcareLoad/obj/Development/LoadDimProcedure.dtsx:
--------------------------------------------------------------------------------
1 |
2 |
17 | 8
19 |
20 |
25 |
26 |
28 |
29 |
30 |
35 |
36 |
44 |
45 |
53 |
61 |
69 |
77 |
86 |
87 |
88 |
89 |
90 |
91 |
92 |
93 |
102 |
103 |
104 |
107 |
108 |
116 |
117 | 0
121 | [dim].[HCPCSProcedure]
125 |
129 |
134 | 1252
138 | false
142 | 3
147 | false
151 | false
155 | TABLOCK,CHECK_CONSTRAINTS
159 | 2147483647
163 |
164 |
165 |
171 |
172 |
173 |
179 |
180 |
188 |
196 |
204 |
205 |
207 |
211 |
217 |
223 |
229 |
230 |
231 |
232 |
233 |
255 |
256 |
257 |
266 |
267 | false
271 |
275 |
276 |
277 |
282 |
283 |
284 |
433 |
460 |
461 |
462 |
463 |
464 |
469 |
470 |
471 |
472 |
473 |
474 |
475 |
476 |
477 |
478 |
480 |
481 |
483 |
484 |
486 |
490 |
491 |
492 |
493 |
495 |
496 |
498 |
502 |
506 |
509 |
510 |
515 |
516 |
518 |
520 |
521 |
522 |
523 |
524 |
525 |
526 |
527 |
528 |
529 |
530 |
531 |
533 |
534 |
535 | DataSourceViewID
536 |
537 |
538 | TableInfoObjectType
539 | Table
541 |
542 |
543 |
544 | ]]>
545 |
--------------------------------------------------------------------------------
/Code/Chapter 11.sql:
--------------------------------------------------------------------------------
1 | --OS and Hardware Concerns
2 | --Transactions
3 | --Transaction Overview
4 | BEGIN TRANSACTION one;
5 | ROLLBACK TRANSACTION one;
6 | GO
7 |
8 | BEGIN TRANSACTION one;
9 | BEGIN TRANSACTION two;
10 | ROLLBACK TRANSACTION two;
11 | GO
12 |
13 | SELECT @@TRANCOUNT;
14 | GO
15 |
16 | USE Master;
17 | GO
18 |
19 | SET RECOVERY FULL;
20 | GO
21 |
22 | EXEC sp_addumpdevice 'disk', 'TestWideWorldImporters ',
23 | 'C:\temp\WideWorldImporters.bak';
24 | EXEC sp_addumpdevice 'disk', 'TestWideWorldImportersLog',
25 | 'C:\temp\WideWorldImportersLog.bak' ;
26 | GO
27 |
28 | SELECT recovery_model_desc
29 | FROM sys.databases
30 | WHERE name = 'WideWorldImporters';
31 | GO
32 |
33 | EXEC sys.sp_dropdevice @logicalname = '';
34 | WideWorldImporters
35 | WideWorldImporters
36 | WideWorldImporters
37 | USE WideWorldImporters;
38 | GO
39 | SELECT COUNT(*)
40 | FROM Sales.SpecialDeals
41 |
42 | BEGIN TRANSACTION Test WITH MARK 'Test';
43 | DELETE Sales.SpecialDeals;
44 | COMMIT TRANSACTION;
45 | SpecialDeals
46 | WideWorldImporters
47 | WideWorldImportersLog
48 | USE Master
49 | GO
50 | WideWorldImporters
51 | WideWorldImporters
52 | WITH REPLACE, NORECOVERY;
53 |
54 | WideWorldImporters
55 | WideWorldImportersLog
56 | WITH STOPBEFOREMARK = 'Test', RECOVERY ;
57 | USE WideWorldImporters;
58 | GO
59 | SELECT COUNT(*)
60 | FROM Sales.SpecialDeals ;
61 | Nested Transactions
62 | BEGIN TRANSACTION;
63 | BEGIN TRANSACTION;
64 | BEGIN TRANSACTION;
65 | SELECT @@TRANCOUNT AS zeroDeep;
66 | BEGIN TRANSACTION;
67 | SELECT @@TRANCOUNT AS oneDeep;
68 | BEGIN TRANSACTION;
69 | SELECT @@TRANCOUNT AS twoDeep;
70 | COMMIT TRANSACTION; --commits previous transaction started with BEGIN TRANSACTION
71 | SELECT @@TRANCOUNT AS oneDeep;
72 | COMMIT TRANSACTION;
73 | SELECT @@TRANCOUNT AS zeroDeep;
74 | BEGIN TRANSACTION;
75 | BEGIN TRANSACTION;
76 | BEGIN TRANSACTION;
77 | BEGIN TRANSACTION;
78 | BEGIN TRANSACTION;
79 | BEGIN TRANSACTION;
80 | BEGIN TRANSACTION;
81 | SELECT @@trancount as InTran;
82 |
83 | ROLLBACK TRANSACTION;
84 | SELECT @@trancount as OutTran ;
85 | SELECT @@TRANCOUNT;
86 | COMMIT TRANSACTION;
87 | Autonomous Transactions
88 | SEQUENCE
89 | IDENTITY
90 | SEQUENCE
91 | IDENTITY
92 | ROLLBACK
93 | SEQUENCE
94 | TABLE
95 | CREATE SCHEMA Magic;
96 | GO
97 | CREATE SEQUENCE Magic.Trick_SEQUENCE AS int START WITH 1;
98 | GO
99 | CREATE TABLE Magic.Trick
100 | (
101 | TrickId int NOT NULL IDENTITY,
102 | Value int CONSTRAINT DFLTTrick_Value DEFAULT (NEXT VALUE FOR Magic.Trick_SEQUENCE)
103 | )
104 | BEGIN TRANSACTION;
105 | INSERT INTO Magic.Trick DEFAULT VALUES; --just use the default values from table
106 | SELECT * FROM Magic.Trick ;
107 | ROLLBACK TRANSACTION;
108 | IDENTITY
109 | SEQUENCE
110 | INSERT
111 | Savepoints
112 | SAVE TRANSACTION ; --savepoint names must follow the same rules for
113 | --identifiers as other objects
114 | CREATE SCHEMA Arts;
115 | GO
116 | CREATE TABLE Arts.Performer
117 | (
118 | PerformerId int IDENTITY CONSTRAINT PKPeformer PRIMARY KEY,
119 | Name varchar(100)
120 | );
121 | GO
122 |
123 | BEGIN TRANSACTION;
124 | INSERT INTO Arts.Performer(Name) VALUES ('Elvis Costello');
125 |
126 | SAVE TRANSACTION savePoint; --the savepoint name is case sensitive, even if instance is not
127 | --if you do the same savepoint twice, the rollback is to latest
128 |
129 | INSERT INTO Arts.Performer(Name) VALUES ('Air Supply');
130 |
131 | --don't insert Air Supply, yuck! ...
132 | ROLLBACK TRANSACTION savePoint;
133 |
134 | COMMIT TRANSACTION;
135 |
136 | SELECT *
137 | FROM Arts.Performer ;
138 | Distributed Transactions
139 | BEGIN TRY
140 | BEGIN DISTRIBUTED TRANSACTION;
141 |
142 | --remote server is a server set up as a linked server
143 |
144 | UPDATE remoteServer.dbName.schemaName.tableName
145 | SET value = 'new value'
146 | WHERE keyColumn = 'value';
147 |
148 | --local server
149 | UPDATE dbName.schemaName.tableName
150 | SET value = 'new value'
151 | WHERE keyColumn = 'value';
152 |
153 | COMMIT TRANSACTION;
154 | END TRY
155 | BEGIN CATCH
156 | ROLLBACK TRANSACTION;
157 | DECLARE @ERRORMessage varchar(2000);
158 | SET @ERRORMessage = ERROR_MESSAGE();
159 | THROW 50000, @ERRORMessage,16;
160 | END CATCH
161 | 'remote proc trans'
162 | BEGIN TRANSACTION
163 | BEGIN DISTRIBUTED TRANSACTION
164 | Transaction State
165 | XACT_STATE(
166 | 1
167 | @@TRANCOUNT
168 | 0
169 | -1
170 | CREATE SCHEMA Menu;
171 | GO
172 | CREATE TABLE Menu.FoodItem
173 | (
174 | FoodItemId int NOT NULL IDENTITY(1,1)
175 | CONSTRAINT PKFoodItem PRIMARY KEY,
176 | Name varchar(30) NOT NULL
177 | CONSTRAINT AKFoodItem_Name UNIQUE,
178 | Description varchar(60) NOT NULL,
179 | CONSTRAINT CHKFoodItem_Name CHECK (LEN(Name) > 0),
180 | CONSTRAINT CHKFoodItem_Description CHECK (LEN(Description) > 0)
181 | );
182 | CREATE TRIGGER Menu.FoodItem$InsertTrigger
183 | ON Menu.FoodItem
184 | AFTER INSERT
185 | AS --Note, minimalist code for demo. Chapter 7 and Appendix B
186 | --have more details on complete trigger writing
187 | BEGIN
188 | BEGIN TRY
189 | IF EXISTS (SELECT *
190 | FROM Inserted
191 | WHERE Description LIKE '%Yucky%')
192 | THROW 50000, 'No ''yucky'' food desired here',1;
193 | END TRY
194 | BEGIN CATCH
195 | IF XACT_STATE() <> 0
196 | ROLLBACK TRANSACTION;
197 | THROW;
198 | END CATCH;
199 | END
200 | GO
201 | ROLLBACK
202 | XACT_ABORT
203 | SET XACT_ABORT ON;
204 |
205 | BEGIN TRY
206 | BEGIN TRANSACTION;
207 |
208 | --insert the row to be tested
209 | INSERT INTO Menu.FoodItem(Name, Description)
210 | VALUES ('Hot Chicken','Nashville specialty, super spicy');
211 |
212 | SELECT XACT_STATE() AS [XACT_STATE], 'Success, commit' AS Description;
213 | COMMIT TRANSACTION;
214 | END TRY
215 | BEGIN CATCH
216 | IF XACT_STATE() = -1 --transaction not doomed, but open
217 | BEGIN
218 | SELECT -1 AS [XACT_STATE], 'Doomed transaction' AS Description;
219 | ROLLBACK TRANSACTION;
220 | END
221 | ELSE IF XACT_STATE() = 0 --transaction not doomed, but open
222 | BEGIN
223 | SELECT 0 AS [XACT_STATE], 'No Transaction' AS Description;;
224 | END
225 | ELSE IF XACT_STATE() = 1 --transaction still active
226 | BEGIN
227 | SELECT 1 AS [XACT_STATE],
228 | 'Transction Still Active After Error' AS Description;
229 | ROLLBACK TRANSACTION;
230 | END
231 | END CATCH ;
232 | INSERT INTO Menu.FoodItem(Name, Description)
233 | VALUES ('Ethiopian Mexican Vegan Fusion','' );
234 | INSERT INTO Menu.FoodItem(Name, Description)
235 | VALUES ('Vegan Cheese','Yucky imitation for the real thing');
236 | ALTER TRIGGER Menu.FoodItem$InsertTrigger
237 | ON Menu.FoodItem
238 | AFTER INSERT
239 | AS --Note, minimalist code for demo. Chapter 7 and Appendix B
240 | --have more details on complete trigger writing
241 | BEGIN
242 | IF EXISTS (SELECT *
243 | FROM Inserted
244 | WHERE Description LIKE '%Yucky%')
245 | THROW 50000, 'No ''yucky'' food desired here',1;
246 |
247 | END;
248 | XACT_ABORT
249 | ON
250 | OFF
251 | Explicit vs. Implicit Transactions
252 | CREATE TABLE
253 | ALTER INDEX
254 | SQL Server Concurrency Methods
255 | Isolation Levels
256 | BEGIN TRANSACTION;
257 | UPDATE tableA
258 | SET status = 'UPDATED'
259 | WHERE tableAId = 'value';
260 | BEGIN TRANSACTION;
261 | INSERT tableA (tableAID, Status)
262 | VALUES (100,'NEW');
263 | BEGIN TRANSACTION;
264 | SELECT *
265 | FROM tableA;
266 | READ COMMITTED
267 | SNAPSHOT
268 | SELECT CASE transaction_isolation_level
269 | WHEN 1 THEN 'Read Uncomitted' WHEN 2 THEN 'Read Committed'
270 | WHEN 3 THEN 'Repeatable Read' WHEN 4 THEN 'Serializable'
271 | WHEN 5 THEN 'Snapshot' ELSE 'Something is afoot'
272 | END
273 | FROM sys.dm_exec_sessions
274 | WHERE session_id = @@spid;
275 | SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
276 | SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
277 | Pessimistic Concurrency Enforcement
278 | Lock Types
279 | SERIALIZABLE
280 | Lock Modes
281 | FROM table1 [WITH] ()
282 | join table2 [WITH] ()
283 | SNAPSHOT
284 | Isolation levels and locking
285 | CREATE SCHEMA Art;
286 | GO
287 | CREATE TABLE Art.Artist
288 | (
289 | ArtistId int CONSTRAINT PKArtist PRIMARY KEY
290 | ,Name varchar(30) --no key on value for demo purposes
291 | ,Padding char(4000) default (replicate('a',4000)) --so all rows not on single page
292 |
293 | );
294 | INSERT INTO Art.Artist(ArtistId, Name)
295 | VALUES (1,'da Vinci'),(2,'Micheangelo'), (3,'Donatello'),
296 | (4,'Picasso'),(5,'Dali'), (6,'Jones');
297 | GO
298 | CREATE TABLE Art.ArtWork
299 | (
300 | ArtWorkId int CONSTRAINT PKArtWork PRIMARY KEY
301 | ,ArtistId int NOT NULL
302 | CONSTRAINT FKArtwork$wasDoneBy$Art_Artist REFERENCES Art.Artist (ArtistId)
303 | ,Name varchar(30)
304 | ,Padding char(4000) default (replicate('a',4000)) --so all rows not on single page
305 | ,CONSTRAINT AKArtwork UNIQUE (ArtistId, Name)
306 | );
307 | INSERT Art.Artwork (ArtworkId, ArtistId, Name)
308 | VALUES (1,1,'Last Supper'),(2,1,'Mona Lisa'),(3,6,'Rabbit Fire');
309 | GO
310 | READ UNCOMMITTED
311 | READ UNCOMMITTED
312 | Art.Artist
313 | --CONNECTION A
314 | SET TRANSACTION ISOLATION LEVEL READ COMMITTED; --this is the default, just
315 | --setting for emphasis
316 | BEGIN TRANSACTION;
317 | INSERT INTO Art.Artist(ArtistId, Name)
318 | VALUES (7, 'McCartney' );
319 | --CONNECTION B
320 | SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
321 | SELECT ArtistId, Name
322 | FROM Art.Artist
323 | WHERE Name = 'McCartney' ;
324 | --CONNECTION B
325 | SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED;
326 | SELECT ArtistId, Name
327 | FROM Art.Artist
328 | WHERE Name = 'McCartney' ;
329 | --CONNECTION A
330 | ROLLBACK TRANSACTION;
331 | --CONNECTION A
332 | SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
333 |
334 | BEGIN TRANSACTION;
335 | SELECT ArtistId, Name FROM Art.Artist WHERE ArtistId = 7;
336 | --CONNECTION B
337 | INSERT INTO Art.Artist(ArtistId, Name)
338 | VALUES (7, 'McCartney');
339 | --CONNECTION A
340 | SELECT ArtistId, Name FROM Art.Artist WHERE ArtistId = 7;
341 | --CONNECTION B
342 | UPDATE Art.Artist SET Name = 'Starr' WHERE ArtistId = 7;
343 | --CONNECTION A
344 | SELECT ArtistId, Name FROM Art.Artist WHERE ArtistId = 7;
345 | COMMIT TRANSACTION;
346 | --CONNECTION A
347 | SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
348 |
349 | BEGIN TRANSACTION;
350 | SELECT ArtistId, Name FROM Art.Artist WHERE ArtistId >= 6;
351 | --CONNECTION B
352 | INSERT INTO Art.Artist(ArtistId, Name)
353 | VALUES (8, 'McCartney');
354 | --CONNECTION B
355 | DELETE Art.Artist
356 | WHERE ArtistId = 6 ;
357 | SELECT *
358 | FROM dbo.testIsolationLevel
359 | --CONNECTION A
360 | SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
361 |
362 | BEGIN TRANSACTION;
363 | SELECT ArtistId, Name FROM Art.Artist;
364 | --CONNECTION B
365 | INSERT INTO Art.Artist(ArtistId, Name)
366 | VALUES (9, 'Vuurmann'); --Misspelled on purpose. Used in later example
367 | --CONNECTION A
368 | COMMIT TRANSACTION;
369 | SELECT ArtistId, Name FROM Art.Artist;
370 | Interesting cases
371 | --CONNECTION A
372 | BEGIN TRANSACTION;
373 | INSERT INTO Art.ArtWork(ArtWorkId, ArtistId, Name)
374 | VALUES (4,9,'Revolver Album Cover');
375 | --CONNECTION B
376 | DELETE FROM Art.Artist WHERE ArtistId = 9;
377 | -- CONNECTION A
378 | COMMIT TRANSACTION;
379 | --CONNECTION A
380 | BEGIN TRANSACTION;
381 | INSERT INTO Art.ArtWork(ArtWorkId, ArtistId, Name)
382 | VALUES (5,9,'Liverpool Rascals' );
383 | --CONNECTION B
384 | UPDATE Art.Artist
385 | SET Name = 'Voorman'
386 | WHERE artistId = 9;
387 | --CONNECTION A
388 | ROLLBACK TRANSACTION;
389 | SELECT * FROM Art.Artwork WHERE ArtistId = 9 ;
390 | @LockOwner
391 | Session
392 | sp_releaseAppLock
393 | --CONNECTION A
394 |
395 | BEGIN TRANSACTION;
396 | DECLARE @result int;
397 | EXEC @result = sp_getapplock @Resource = 'invoiceId=1', @LockMode = 'Exclusive';
398 | SELECT @result;
399 | APPLOCK_MODE()
400 | SELECT APPLOCK_MODE('public','invoiceId=1');
401 | Exclusive
402 | --CONNECTION B
403 | BEGIN TRANSACTION;
404 | DECLARE @result int;
405 | EXEC @result = sp_getapplock @Resource = 'invoiceId=1', @LockMode = 'Exclusive';
406 | SELECT @result;
407 | --CONNECTION B
408 | BEGIN TRANSACTION;
409 | SELECT APPLOCK_TEST('public','invoiceId=1','Exclusive','Transaction') as CanTakeLock
410 | ROLLBACK TRANSACTION ;
411 | CREATE SCHEMA Demo;
412 | GO
413 | CREATE TABLE Demo.Applock
414 | (
415 | ApplockId int CONSTRAINT PKApplock PRIMARY KEY,
416 | --the value that we will be generating
417 | --with the procedure
418 | ConnectionId int, --holds the spid of the connection so you can
419 | --who creates the row
420 | InsertTime datetime2(3) DEFAULT (SYSDATETIME()) --the time the row was created, so
421 | --you can see the progression
422 | );
423 | CREATE PROCEDURE Demo.Applock$test
424 | (
425 | @ConnectionId int,
426 | @UseApplockFlag bit = 1,
427 | @StepDelay varchar(10) = '00:00:00'
428 | ) AS
429 | SET NOCOUNT ON
430 | BEGIN TRY
431 | BEGIN TRANSACTION
432 | DECLARE @retval int = 1;
433 | IF @UseApplockFlag = 1 --turns on and off the applock for testing
434 | BEGIN
435 | EXEC @retval = sp_getAppLock @Resource = 'applock$test',
436 | @LockMode = 'exclusive';
437 | IF @retval < 0
438 | BEGIN
439 | DECLARE @errorMessage nvarchar(200);
440 | SET @errorMessage =
441 | CASE @retval
442 | WHEN -1 THEN 'Applock request timed out.'
443 | WHEN -2 THEN 'Applock request canceled.'
444 | WHEN -3 THEN 'Applock involved in deadlock'
445 | ELSE 'Parameter validation or other call error.'
446 | END;
447 | THROW 50000,@errorMessage,16;
448 | END;
449 | END;
450 |
451 | --get the next primary key value. Reality case is a far more complex number generator
452 | --that couldn't be done with a sequence or identity
453 | DECLARE @ApplockId int;
454 | SET @ApplockId = COALESCE((SELECT MAX(ApplockId) FROM Demo.Applock),0) + 1;
455 |
456 | --delay for parameterized amount of time to slow down operations
457 | --and guarantee concurrency problems
458 | WAITFOR DELAY @stepDelay;
459 |
460 | --insert the next value
461 | INSERT INTO Demo.Applock(ApplockId, connectionId)
462 | VALUES (@ApplockId, @ConnectionId);
463 |
464 | --won't have much effect on this code, since the row will now be
465 | --exclusively locked, and the max will need to see the new row to
466 | --be of any effect.
467 | IF @useApplockFlag = 1 --turns on and off the applock for testing
468 | EXEC @retval = sp_releaseApplock @Resource = 'applock$test';
469 |
470 | --this releases the applock too
471 | COMMIT TRANSACTION;
472 | END TRY
473 | BEGIN CATCH
474 | --if there is an error, roll back and display it.
475 | IF XACT_STATE() <> 0
476 | ROLLBACK TRANSACTION;
477 | SELECT CAST(ERROR_NUMBER() as varchar(10)) + ':' + ERROR_MESSAGE();
478 | END CATCH;
479 | --test on multiple connections
480 | WAITFOR TIME '21:47'; --set for a time to run so multiple batches
481 | --can simultaneously execute
482 | go
483 | EXEC Demo.Applock$test @connectionId = @@spid
484 | ,@useApplockFlag = 0 -- <1=use applock, 0 = don't use applock>
485 | ,@stepDelay = '00:00:00.001'--'delay in hours:minutes:seconds.parts of seconds';
486 | GO 10000 --runs the batch 10000 times in SSMS
487 | SET @applockId =
488 | COALESCE((SELECT MAX(applockId)
489 | FROM APPLOCK WITH (UPDLOCK,PAGLOCK)),0) + 1;
490 | Optimistic Concurrency Enforcement
491 | Optimistic Concurrency Enforcement in On-Disk Tables
492 | ALTER DATABASE Chapter11
493 | SET ALLOW_SNAPSHOT_ISOLATION ON;
494 | Art.Artist
495 | --CONNECTION A
496 | SET TRANSACTION ISOLATION LEVEL SNAPSHOT;
497 | BEGIN TRANSACTION;
498 | SELECT ArtistId, Name FROM Art.Artist;
499 | --CONNECTION B
500 | INSERT INTO Art.Artist(ArtistId, Name)
501 | VALUES (10, 'Disney');
502 | --CONNECTION B
503 | DELETE FROM Art.Artist
504 | WHERE ArtistId = 3;
505 | --CONNECTION A
506 | SELECT ArtistId, Name FROM Art.Artist ;
507 |
508 |
509 |
510 |
511 | --CONNECTION A
512 | SET TRANSACTION ISOLATION LEVEL SNAPSHOT;
513 | BEGIN TRANSACTION;
514 |
515 | UPDATE Art.Artist
516 | SET Name = 'Duh Vinci'
517 | WHERE ArtistId = 1;
518 | --CONNECTION B
519 | SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
520 | BEGIN TRANSACTION;
521 |
522 | UPDATE Art.Artist
523 | SET Name = 'Dah Vinci'
524 | WHERE ArtistId = 1;
525 | --CONNECTION A
526 | SET TRANSACTION ISOLATION LEVEL SNAPSHOT;
527 | BEGIN TRANSACTION;
528 | SELECT *
529 | FROM Art.Artist;
530 |
531 | --CONNECTION B
532 | UPDATE Art.Artist
533 | SET Name = 'Dah Vinci'
534 | WHERE ArtistId = 1;
535 | --CONNECTION A
536 | UPDATE Art.Artist
537 | SET Name = 'Duh Vinci'
538 | WHERE ArtistId = 1;
539 | READ COMMITTED
540 | --must be no active connections other than the connection executing
541 | --this ALTER command
542 | ALTER DATABASE Chapter11
543 | SET READ_COMMITTED_SNAPSHOT ON;
544 | BEGIN TRANSACTION
545 | SELECT column FROM table1
546 | --midpoint
547 | SELECT column FROM table1
548 | COMMIT TRANSACTION
549 | --CONNECTION A
550 | SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
551 | BEGIN TRANSACTION;
552 | SELECT ArtistId, Name FROM Art.Artist;
553 | --CONNECTION B
554 | BEGIN TRANSACTION;
555 | INSERT INTO Art.Artist (ArtistId, Name)
556 | VALUES (11, 'Freling' )
557 |
558 | --CONNECTION A
559 | SELECT ArtistId, Name FROM Art.Artist;
560 |
561 |
562 | --CONNECTION B (still in a transaction)
563 | UPDATE Art.Artist
564 | SET Name = UPPER(Name)
565 |
566 | --CONNECTION A
567 | SELECT ArtistId, Name FROM Art.Artist;
568 | --CONNECTION B
569 | COMMIT;
570 |
571 | --CONNECTION A
572 | SELECT ArtistId, Name FROM Art.Artist;
573 | COMMIT;
574 | Optimistic Concurrency Enforcement in In-Memory OLTP Tables
575 | CONNECTION B
576 | TableNameId
577 | 'Canada'
578 | CONNECTION B
579 | CONNECTION B
580 | CONNECTION A
581 | CONNECTION A
582 | Country='USA'
583 | CONNECTION A
584 | SNAPSHOT
585 | REPEATABLE READ
586 | SERIALIZABLE
587 | REPEATABLE READ
588 | SERIALIZABLE
589 | SNAPSHOT
590 | COMMIT
591 | SNAPSHOT
592 | --The download will include the code to add an in-memory filegroup
593 |
594 | CREATE SCHEMA Art_InMem;
595 | GO
596 | CREATE TABLE Art_InMem.Artist
597 | (
598 | ArtistId int CONSTRAINT PKArtist PRIMARY KEY
599 | NONCLUSTERED HASH WITH (BUCKET_COUNT=100)
600 | ,Name varchar(30) --no key on value for demo purposes, just like on-disk example
601 | ,Padding char(4000) --can't use REPLICATE in in-memory OLTP, so will use in INSERT
602 |
603 | ) WITH ( MEMORY_OPTIMIZED = ON );
604 |
605 | INSERT INTO Art_InMem.Artist(ArtistId, Name,Padding)
606 | VALUES (1,'da Vinci',REPLICATE('a',4000)),(2,'Micheangelo',REPLICATE('a',4000)),
607 | (3,'Donatello',REPLICATE('a',4000)),(4,'Picasso',REPLICATE('a',4000)),
608 | (5,'Dali',REPLICATE('a',4000)), (6,'Jones',REPLICATE('a',4000));
609 | GO
610 |
611 | CREATE TABLE Art_InMem.ArtWork
612 | (
613 | ArtWorkId int CONSTRAINT PKArtWork PRIMARY KEY
614 | NONCLUSTERED HASH WITH (BUCKET_COUNT=100)
615 | ,ArtistId int NOT NULL
616 | CONSTRAINT FKArtwork$wasDoneBy$Art_Artist REFERENCES Art_InMem.Artist (ArtistId)
617 | ,Name varchar(30)
618 | ,Padding char(4000) --can't use REPLICATE in in-memory OLTP, so will use in INSERT
619 | ,CONSTRAINT AKArtwork UNIQUE NONCLUSTERED (ArtistId, Name)
620 | ) WITH ( MEMORY_OPTIMIZED = ON );
621 |
622 | INSERT Art_InMem.Artwork (ArtworkId, ArtistId, Name,Padding)
623 | VALUES (1,1,'Last Supper',REPLICATE('a',4000)),(2,1,'Mona Lisa',REPLICATE('a',4000)),
624 | (3,6,'Rabbit Fire',REPLICATE('a',4000 ));
625 | INSERT INTO InMemTable
626 | SELECT *
627 | FROM DBOtherThanTempdb.SchemaName.Tablename;
628 | SELECT ArtistId, Name
629 | FROM Art_Inmem.Artist;
630 | BEGIN TRANSACTION;
631 | SELECT ArtistId, Name
632 | FROM Art_Inmem.Artist;
633 | COMMIT TRANSACTION ;
634 | REPEATABLE READ
635 | SET TRANSACTION ISOLATION LEVEL REPEATABLE READ
636 | BEGIN TRANSACTION;
637 | SELECT ArtistId, Name
638 | FROM Art_Inmem.Artist WITH (REPEATABLEREAD );
639 | COMMIT TRANSACTION;
640 | BEGIN TRANSACTION;
641 | SELECT ArtistId, Name
642 | FROM Art_Inmem.Artist WITH (SNAPSHOT);
643 | COMMIT TRANSACTION;
644 | ALTER DATABASE LetMeFinish
645 | SET MEMORY_OPTIMIZED_ELEVATE_TO_SNAPSHOT ON;
646 | SNAPSHOT
647 | REPEATABLE READ
648 | SERIALIZABLE
649 | SNAPSHOT
650 | CONNECTION A
651 | CONNECTION B
652 | --CONNECTION A
653 | BEGIN TRANSACTION;
654 |
655 | --CONNECTION B
656 | INSERT INTO Art_InMem.Artist(ArtistId, Name)
657 | VALUES (7, 'McCartney');
658 | --CONNECTION A
659 | SELECT ArtistId, Name
660 | FROM Art_InMem.Artist WITH (SNAPSHOT)
661 | WHERE ArtistId >= 5;
662 | BEGIN TRANSACTION
663 | Artist
664 | CONNECTION B
665 | ArtistId = 6
666 | --CONNECTION B
667 | INSERT INTO Art_InMem.Artist(ArtistId, Name)
668 | VALUES (8, 'Starr');
669 |
670 | INSERT INTO Art_InMem.Artwork(ArtworkId, ArtistId, Name)
671 | VALUES (4,7,'The Kiss');
672 |
673 | DELETE FROM Art_InMem.Artist WHERE ArtistId = 5;
674 | --CONNECTION A
675 | SELECT ArtistId, Name
676 | FROM Art_InMem.Artist WITH (SNAPSHOT)
677 | WHERE ArtistId >= 5;
678 |
679 | SELECT COUNT(*)
680 | FROM Art_InMem.Artwork WITH (SNAPSHOT);
681 | COMMIT
682 | ROLLBACK
683 | CONNECTION A
684 | --CONNECTION A
685 | COMMIT;
686 |
687 | SELECT ArtistId, Name
688 | FROM Art_InMem.Artist WITH (SNAPSHOT)
689 | WHERE ArtistId >= 5;
690 |
691 | SELECT COUNT(*)
692 | FROM Art_InMem.Artwork WITH (SNAPSHOT);
693 | CONNECTION A
694 | CONNECTION B
695 | CONNECTION B
696 | CONNECTION B
697 | REPEATABLE READ
698 | --CONNECTION A
699 | BEGIN TRANSACTION;
700 | SELECT ArtistId, Name
701 | FROM Art_InMem.Artist WITH (REPEATABLEREAD)
702 | WHERE ArtistId >= 8;
703 | --CONNECTION B
704 | INSERT INTO Art_InMem.Artist(ArtistId, Name)
705 | VALUES (9,'Groening');
706 | --CONNECTION A
707 | SELECT ArtistId, Name
708 | FROM Art_InMem.Artist WITH (SNAPSHOT)
709 | WHERE ArtistId >= 8;
710 | COMMIT;
711 | SELECT ArtistId, Name
712 | FROM Art_InMem.Artist WITH (SNAPSHOT)
713 | WHERE ArtistId >= 8;
714 | CONNECTION A
715 | --CONNECTION A
716 | BEGIN TRANSACTION;
717 | SELECT ArtistId, Name
718 | FROM Art_InMem.Artist WITH (REPEATABLEREAD)
719 | WHERE ArtistId >= 8;
720 |
721 | --CONNECTION B
722 | DELETE FROM Art_InMem.Artist WHERE ArtistId = 9; --Not because I don't love Matt!
723 | --CONNECTION A
724 | SELECT ArtistId, Name
725 | FROM Art_InMem.Artist WITH (SNAPSHOT)
726 | WHERE ArtistId >= 8;
727 | COMMIT;
728 | SELECT ArtistId, Name
729 | FROM Art_InMem.Artist WITH (SNAPSHOT)
730 | WHERE ArtistId >= 8;
731 | REPEATABLE READ
732 | --CONNECTION A
733 | BEGIN TRANSACTION;
734 | SELECT ArtistId, Name
735 | FROM Art_InMem.Artist WITH (SERIALIZABLE)
736 | WHERE ArtistId >= 8;
737 | --CONNECTION B
738 | INSERT INTO Art_InMem.Artist(ArtistId, Name)
739 | VALUES (9,'Groening'); --See, brought him back!
740 | --CONNECTION A
741 | SELECT ArtistId, Name
742 | FROM Art_InMem.Artist WITH (SNAPSHOT)
743 | WHERE ArtistId >= 8;
744 | COMMIT;
745 | SELECT ArtistId, Name
746 | FROM Art_InMem.Artist WITH (SERIALIZABLE)
747 | WHERE ArtistId >= 8;
748 | Name
749 | CONNECTION A
750 | --CONNECTION A
751 | BEGIN TRANSACTION;
752 | SELECT ArtistId, Name
753 | FROM Art_InMem.Artist WITH (SERIALIZABLE)
754 | WHERE Name = 'Starr';
755 | --CONNECTION B
756 | UPDATE Art_InMem.Artist WITH (SNAPSHOT) --default to snapshot, but the change itself
757 | --behaves the same in any isolation level
758 | SET Padding = REPLICATE('a',4000) --just make a change
759 | WHERE Name = 'McCartney';
760 | --CONNECTION A
761 | COMMIT;
762 | ALTER TABLE Art_InMem.Artist
763 | ADD CONSTRAINT AKArtist UNIQUE NONCLUSTERED (Name) --A string column may be used to
764 | --do ordered scans,
765 | --particularly one like name
766 | CONNECTION A
767 | CONNECTION B
768 | --CONNECTION A
769 | BEGIN TRANSACTION;
770 | UPDATE Art_InMem.Artist WITH (SNAPSHOT)
771 | SET Padding = REPLICATE('a',4000) --just make a change
772 | WHERE Name = 'McCartney';
773 | CONNECTION B
774 | --CONNECTION B
775 | BEGIN TRANSACTION;
776 | UPDATE Art_InMem.Artist WITH (SNAPSHOT)
777 | SET Padding = REPLICATE('a',4000) --just make a change
778 | WHERE Name = 'McCartney';
779 | --CONNECTION A
780 | ROLLBACK TRANSACTION --from previous example
781 | BEGIN TRANSACTION
782 | INSERT INTO Art_InMem.Artist (ArtistId, Name)
783 | VALUES (11,'Wright');
784 |
785 | --CONNECTION B
786 | BEGIN TRANSACTION;
787 | INSERT INTO Art_InMem.Artist (ArtistId, Name)
788 | VALUES (12,'Wright');
789 | --CONNECTION A
790 | COMMIT;
791 | --CONNECTION B
792 | COMMIT;
793 | UNIQUE
794 | INSERT
795 | --CONNECTION A
796 | BEGIN TRANSACTION;
797 | DELETE FROM Art_InMem.Artist WITH (SNAPSHOT)
798 | WHERE ArtistId = 4;
799 | --CONNECTION B --in or out of transaction
800 | INSERT INTO Art_InMem.Artist (ArtistId, Name)
801 | VALUES (4,'Picasso')
802 | Name
803 | PRIMARY KEY
804 | ROLLBACK
805 | --CONNECTION A
806 | ROLLBACK; --We like Picasso
807 | --CONNECTION A
808 | BEGIN TRANSACTION
809 | INSERT INTO Art_InMem.Artwork(ArtworkId, ArtistId, Name)
810 | VALUES (5,4,'The Old Guitarist');
811 | --CONNECTION B
812 | UPDATE Art_InMem.Artist WITH (SNAPSHOT)
813 | SET Padding = REPLICATE('a',4000) --just make a change
814 | WHERE ArtistId = 4;
815 | --CONNECTION A
816 | COMMIT;
817 | Coding for Ascynronous Contention
818 | UPDATE
819 | Row-Based Change Detection
820 | Adding Validation Columns
821 | CREATE SCHEMA Hr;
822 | GO
823 | CREATE TABLE Hr.person
824 | (
825 | PersonId int IDENTITY(1,1) CONSTRAINT PKPerson primary key,
826 | FirstName varchar(60) NOT NULL,
827 | MiddleName varchar(60) NOT NULL,
828 | LastName varchar(60) NOT NULL,
829 |
830 | DateOfBirth date NOT NULL,
831 | RowLastModifyTime datetime2(3) NOT NULL
832 | CONSTRAINT DFLTPerson_RowLastModifyTime DEFAULT (SYSDATETIME()),
833 | RowModifiedByUserIdentifier nvarchar(128) NOT NULL
834 | CONSTRAINT DFLTPerson_RowModifiedByUserIdentifier DEFAULT suser_sname()
835 |
836 | );
837 | UPDATE
838 | CREATE TRIGGER Hr.Person$InsteadOfUpdateTrigger
839 | ON Hr.Person
840 | INSTEAD OF UPDATE AS
841 | BEGIN
842 |
843 | --stores the number of rows affected
844 | DECLARE @rowsAffected int = @@rowcount,
845 | @msg varchar(2000) = ''; --used to hold the error message
846 |
847 | --no need to continue on if no rows affected
848 | IF @rowsAffected = 0 RETURN;
849 |
850 | SET NOCOUNT ON; --to avoid the rowcount messages
851 | SET ROWCOUNT 0; --in case the client has modified the rowcount
852 |
853 | BEGIN TRY
854 | --[validation blocks]
855 | --[modification blocks]
856 | --remember to update ALL columns when building instead of triggers
857 | UPDATE Hr.Person
858 | SET FirstName = inserted.FirstName,
859 | MiddleName = inserted.MiddleName,
860 | LastName = inserted.LastName,
861 | DateOfBirth = inserted.DateOfBirth,
862 | RowLastModifyTime = default, -- set the value to the default
863 | RowModifiedByUserIdentifier = default
864 | FROM Hr.Person
865 | JOIN inserted
866 | on Person.PersonId = inserted.PersonId;
867 | END TRY
868 | BEGIN CATCH
869 | IF XACT_STATE() > 0
870 | ROLLBACK TRANSACTION;
871 |
872 | THROW; --will halt the batch or be caught by the caller's catch block
873 |
874 | END CATCH;
875 | END;
876 | INSERT INTO Hr.Person (FirstName, MiddleName, LastName, DateOfBirth)
877 | VALUES ('Paige','O','Anxtent','19691212');
878 |
879 | SELECT *
880 | FROM Hr.Person;
881 | UPDATE Hr.Person
882 | SET MiddleName = 'Ona'
883 | WHERE PersonId = 1;
884 |
885 | SELECT RowLastModifyTime
886 | FROM Hr.Person;
887 | INSERT
888 | rowversion
889 | ALTER TABLE hr.person
890 | ADD RowVersion rowversion;
891 | GO
892 | SELECT PersonId, RowVersion
893 | FROM Hr.Person;
894 | UPDATE Hr.Person
895 | SET FirstName = 'Paige' --no actual change occurs
896 | WHERE PersonId = 1;
897 | Coding for Row-Level Change Detection
898 | UPDATE Hr.Person
899 | SET FirstName = 'Headley'
900 | WHERE PersonId = 1 --include the key, even when changing the key value if allowed
901 | --non-key columns
902 | and FirstName = 'Paige'
903 | and MiddleName = 'ona'
904 | and LastName = 'Anxtent'
905 | and DateOfBirth = '19691212' ;
906 | IF EXISTS ( SELECT *
907 | FROM Hr.Person
908 | WHERE PersonId = 1) --check for existence of the primary key
909 | --raise an error stating that the row no longer exists
910 | ELSE
911 | --raise an error stating that another user has changed the row
912 | UPDATE Hr.Person
913 | SET FirstName = 'Fred'
914 | WHERE PersonId = 1 --include the key
915 | AND RowLastModifyTime = '2016-06-11 14:52:50.154';
916 | UPDATE Hr.Person
917 | SET FirstName = 'Fred'
918 | WHERE PersonId = 1
919 | and RowVersion = 0x00000000000007D4;
920 | DELETE FROM Hr.Person
921 | WHERE PersonId = 1
922 | And Rowversion = 0x00000000000007D5;
923 | Coding for Logical Unit of Work Change Detection
924 | CREATE SCHEMA Invoicing;
925 | GO
926 | --leaving off who invoice is for, like an account or person name
927 | CREATE TABLE Invoicing.Invoice
928 | (
929 | InvoiceId int IDENTITY(1,1),
930 | Number varchar(20) NOT NULL,
931 | ObjectVersion rowversion not null,
932 | CONSTRAINT PKInvoice PRIMARY KEY (InvoiceId)
933 | );
934 | --also ignoring what product that the line item is for
935 | CREATE TABLE Invoicing.InvoiceLineItem
936 |
937 | (
938 | InvoiceLineItemId int NOT NULL,
939 | InvoiceId int NULL,
940 | ItemCount int NOT NULL,
941 | Cost int NOT NULL,
942 | CONSTRAINT PKInvoiceLineItem primary key (invoiceLineItemId),
943 | CONSTRAINT FKInvoiceLineItem$references$Invoicing_Invoice
944 | FOREIGN KEY (InvoiceId) REFERENCES Invoicing.Invoice(InvoiceId)
945 | );
946 | CREATE PROCEDURE InvoiceLineItem$del
947 | (
948 | @InvoiceId int, --we pass this because the client should have it
949 | --with the invoiceLineItem row
950 | @InvoiceLineItemId int,
951 | @ObjectVersion rowversion
952 | ) as
953 | BEGIN
954 | --gives us a unique savepoint name, trim it to 125
955 | --characters if the user named it really large
956 | DECLARE @savepoint nvarchar(128) =
957 | CAST(OBJECT_NAME(@@procid) AS nvarchar(125)) +
958 | CAST(@@nestlevel AS nvarchar(3));
959 | --get initial entry level, so we can do a rollback on a doomed transaction
960 | DECLARE @entryTrancount int = @@trancount;
961 |
962 | BEGIN TRY
963 | BEGIN TRANSACTION;
964 | SAVE TRANSACTION @savepoint;
965 |
966 | --tweak the ObjectVersion on the Invoice Table
967 | UPDATE Invoicing.Invoice
968 | SET Number = Number
969 | WHERE InvoiceId = @InvoiceId
970 | And ObjectVersion = @ObjectVersion;
971 |
972 | IF @@Rowcount = 0
973 | THROW 50000,'The InvoiceId no longer exists or has been changed',1;
974 |
975 | DELETE Invoicing.InvoiceLineItem
976 | FROM InvoiceLineItem
977 | WHERE InvoiceLineItemId = @InvoiceLineItemId;
978 |
979 | COMMIT TRANSACTION;
980 |
981 | END TRY
982 | BEGIN CATCH
983 |
984 | --if the tran is doomed, and the entryTrancount was 0,
985 | --we can roll back
986 | IF XACT_STATE ()= -1 AND @entryTrancount = 0
987 | ROLLBACK TRANSACTION;
988 |
989 | --otherwise, we can still save the other activities in the
990 | --transaction.
991 | ELSE IF XACT_STATE() = 1 --transaction not doomed, but open
992 | BEGIN
993 | ROLLBACK TRANSACTION @savepoint;
994 | COMMIT TRANSACTION;
995 | END;
996 |
997 | DECLARE @ERRORmessage nvarchar(4000)
998 | SET @ERRORmessage = 'Error occurred in procedure ''' +
999 | OBJECT_NAME (@@procid) + ''', Original Message: '''
1000 | + ERROR_MESSAGE() + '''';
1001 | THROW 50000,@ERRORmessage,1;
1002 | RETURN -100;
1003 |
1004 | END CATCH;
1005 | END ;
1006 | Best Practices
1007 | Summary
1008 |
--------------------------------------------------------------------------------
/Code/Chapter 07.sql:
--------------------------------------------------------------------------------
1 | --CREATE DATABASE Chapter7
2 | --go
3 | --Use Chapter7
4 | --go
5 |
6 | Use Chapter7
7 | GO
8 |
9 | DROP TABLE IF EXISTS Music.Album, Music.Publisher, Music.Artist;
10 | GO
11 | DROP SCHEMA IF EXISTS Music;
12 | GO
13 |
14 | ---Check Constraints
15 |
16 | CREATE SCHEMA Music;
17 | GO
18 | CREATE TABLE Music.Artist
19 | (
20 | ArtistId int NOT NULL,
21 | Name varchar(60) NOT NULL,
22 |
23 | CONSTRAINT PKArtist PRIMARY KEY CLUSTERED (ArtistId),
24 | CONSTRAINT PKArtist_Name UNIQUE NONCLUSTERED (Name)
25 | );
26 | CREATE TABLE Music.Publisher
27 | (
28 | PublisherId int CONSTRAINT PKPublisher PRIMARY KEY,
29 | Name varchar(20),
30 | CatalogNumberMask varchar(100)
31 | CONSTRAINT DFLTPublisher_CatalogNumberMask DEFAULT ('%'),
32 | CONSTRAINT AKPublisher_Name UNIQUE NONCLUSTERED (Name),
33 | );
34 |
35 | CREATE TABLE Music.Album
36 | (
37 | AlbumId int NOT NULL,
38 | Name varchar(60) NOT NULL,
39 | ArtistId int NOT NULL,
40 | CatalogNumber varchar(20) NOT NULL,
41 | PublisherId int NOT NULL
42 |
43 | CONSTRAINT PKAlbum PRIMARY KEY CLUSTERED(AlbumId),
44 | CONSTRAINT AKAlbum_Name UNIQUE NONCLUSTERED (Name),
45 | CONSTRAINT FKArtist$records$Music_Album
46 | FOREIGN KEY (ArtistId) REFERENCES Music.Artist(ArtistId),
47 | CONSTRAINT FKPublisher$Published$Music_Album
48 | FOREIGN KEY (PublisherId) REFERENCES Music.Publisher(PublisherId)
49 | );
50 | GO
51 |
52 | INSERT INTO Music.Publisher (PublisherId, Name, CatalogNumberMask)
53 | VALUES (1,'Capitol',
54 | '[0-9][0-9][0-9]-[0-9][0-9][0-9a-z][0-9a-z][0-9a-z]-[0-9][0-9]'),
55 | (2,'MCA', '[a-z][a-z][0-9][0-9][0-9][0-9][0-9]');
56 |
57 | INSERT INTO Music.Artist(ArtistId, Name)
58 | VALUES (1, 'The Beatles'),(2, 'The Who');
59 |
60 | INSERT INTO Music.Album (AlbumId, Name, ArtistId, PublisherId, CatalogNumber)
61 | VALUES (1, 'The White Album',1,1,'433-43ASD-33'),
62 | (2, 'Revolver',1,1,'111-11111-11'),
63 | (3, 'Quadrophenia',2,2,'CD12345');
64 | GO
65 |
66 |
67 | ALTER TABLE Music.Artist WITH CHECK
68 | ADD CONSTRAINT CHKArtist$Name$NoPetShopNames
69 | CHECK (Name NOT LIKE '%Pet%Shop%');
70 | GO
71 |
72 | INSERT INTO Music.Artist(ArtistId, Name)
73 | VALUES (3, 'Pet Shop Boys');
74 | GO
75 |
76 | INSERT INTO Music.Artist(ArtistId, Name)
77 | VALUES (3, 'Madonna');
78 | GO
79 |
80 | ALTER TABLE Music.Artist WITH CHECK
81 | ADD CONSTRAINT CHKArtist$Name$noMadonnaNames
82 | CHECK (Name NOT LIKE '%Madonna%');
83 | GO
84 |
85 | ALTER TABLE Music.Artist WITH NOCHECK
86 | ADD CONSTRAINT CHKArtist$Name$noMadonnaNames
87 | CHECK (Name NOT LIKE '%Madonna%');
88 | GO
89 |
90 | UPDATE Music.Artist
91 | SET Name = Name;
92 | GO
93 |
94 |
95 | SELECT definition, is_not_trusted
96 | FROM sys.check_constraints
97 | WHERE object_schema_name(object_id) = 'Music'
98 | AND name = 'CHKArtist$Name$noMadonnaNames';
99 | GO
100 |
101 |
102 | ALTER TABLE Music.Artist WITH CHECK CHECK CONSTRAINT CHKArtist$Name$noMadonnaNames;
103 | GO
104 |
105 | DELETE FROM Music.Artist
106 | WHERE Name = 'Madonna';
107 | GO
108 |
109 | ALTER TABLE Music.Artist NOCHECK CONSTRAINT CHKArtist$Name$noMadonnaNames;
110 | GO
111 |
112 |
113 | SELECT definition, is_not_trusted, is_disabled
114 | FROM sys.check_constraints
115 | WHERE object_schema_name(object_id) = 'Music'
116 | AND name = 'CHKArtist$Name$noMadonnaNames';
117 | GO
118 |
119 | ALTER TABLE Music.Artist WITH CHECK CHECK CONSTRAINT CHKArtist$Name$noMadonnaNames;
120 | GO
121 |
122 |
123 | -----CHECK Constraints Based on Simple Expressions
124 |
125 | ALTER TABLE Music.Album WITH CHECK
126 | ADD CONSTRAINT CHKAlbum$Name$noEmptyString
127 | CHECK (LEN(Name) > 0); --note,len does a trim by default, so any string
128 | --of all space characters will return 0
129 |
130 | GO
131 |
132 | INSERT INTO Music.Album ( AlbumId, Name, ArtistId, PublisherId, CatalogNumber )
133 | VALUES ( 4, '', 1, 1,'dummy value' );
134 |
135 | ----CHECK Constraints Using Functions
136 |
137 | CREATE FUNCTION Music.Publisher$CatalogNumberValidate
138 | (
139 | @CatalogNumber char(12),
140 | @PublisherId int --now based on the Artist ID
141 | )
142 |
143 | RETURNS bit
144 | AS
145 | BEGIN
146 | DECLARE @LogicalValue bit, @CatalogNumberMask varchar(100);
147 |
148 | SELECT @LogicalValue = CASE WHEN @CatalogNumber LIKE CatalogNumberMask
149 | THEN 1
150 | ELSE 0 END
151 | FROM Music.Publisher
152 | WHERE PublisherId = @PublisherId;
153 |
154 | RETURN @LogicalValue;
155 | END;
156 | GO
157 |
158 |
159 | SELECT Album.CatalogNumber, Publisher.CatalogNumberMask
160 | FROM Music.Album
161 | JOIN Music.Publisher as Publisher
162 | ON Album.PublisherId = Publisher.PublisherId;
163 | GO
164 |
165 | ALTER TABLE Music.Album
166 | WITH CHECK ADD CONSTRAINT
167 | CHKAlbum$CatalogNumber$CatalogNumberValidate
168 | CHECK (Music.Publisher$CatalogNumberValidate
169 | (CatalogNumber,PublisherId) = 1);
170 | GO
171 |
172 | SELECT Album.Name, Album.CatalogNumber, Publisher.CatalogNumberMask
173 | FROM Music.Album
174 | JOIN Music.Publisher
175 | ON Publisher.PublisherId = Album.PublisherId
176 | WHERE Music.Publisher$CatalogNumberValidate(Album.CatalogNumber,Album.PublisherId) <> 1;
177 | GO
178 |
179 | INSERT Music.Album(AlbumId, Name, ArtistId, PublisherId, CatalogNumber)
180 | VALUES (4,'Who''s Next',2,2,'1');
181 | GO
182 |
183 | INSERT Music.Album(AlbumId, Name, ArtistId, CatalogNumber, PublisherId)
184 | VALUES (4,'Who''s Next',2,'AC12345',2);
185 | GO
186 |
187 | SELECT * FROM Music.Album;
188 | GO
189 |
190 | SELECT *
191 | FROM Music.Album AS Album
192 | JOIN Music.Publisher AS Publisher
193 | ON Publisher.PublisherId = Album.PublisherId
194 | WHERE Music.Publisher$CatalogNumberValidate
195 | (Album.CatalogNumber, Album.PublisherId) <> 1;
196 |
197 |
198 | ----Enhancing Errors Caused by Constraints
199 |
200 | CREATE SCHEMA ErrorHandling; --used to hold objects for error management purposes
201 | GO
202 | CREATE TABLE ErrorHandling.ErrorMap
203 | (
204 | ConstraintName sysname NOT NULL CONSTRAINT PKErrorMap PRIMARY KEY,
205 | Message varchar(2000) NOT NULL
206 | );
207 | GO
208 |
209 | INSERT ErrorHandling.ErrorMap(constraintName, message)
210 | VALUES ('CHKAlbum$CatalogNumber$CatalogNumberValidate',
211 | 'The catalog number does not match the format set up by the Publisher');
212 | GO
213 |
214 | CREATE PROCEDURE ErrorHandling.ErrorMap$MapError
215 | (
216 | @ErrorNumber int = NULL,
217 | @ErrorMessage nvarchar(2000) = NULL,
218 | @ErrorSeverity INT= NULL
219 |
220 | ) AS
221 | BEGIN
222 | SET NOCOUNT ON
223 |
224 | --use values in ERROR_ functions unless the user passes in values
225 | SET @ErrorNumber = Coalesce(@ErrorNumber, ERROR_NUMBER());
226 | SET @ErrorMessage = Coalesce(@ErrorMessage, ERROR_MESSAGE());
227 | SET @ErrorSeverity = Coalesce(@ErrorSeverity, ERROR_SEVERITY());
228 |
229 | --strip the constraint name out of the error message
230 | DECLARE @constraintName sysname;
231 | SET @constraintName = substring( @ErrorMessage,
232 | CHARINDEX('constraint "',@ErrorMessage) + 12,
233 | CHARINDEX('"',substring(@ErrorMessage,
234 | CHARINDEX('constraint "',@ErrorMessage) +
235 | 12,2000))-1)
236 | --store off original message in case no custom message found
237 | DECLARE @originalMessage nvarchar(2000);
238 | SET @originalMessage = ERROR_MESSAGE();
239 |
240 | IF @ErrorNumber = 547 --constraint error
241 | BEGIN
242 | SET @ErrorMessage =
243 | (SELECT message
244 | FROM ErrorHandling.ErrorMap
245 | WHERE constraintName = @constraintName);
246 | END
247 |
248 | --if the error was not found, get the original message with generic 50000 error number
249 | SET @ErrorMessage = ISNULL(@ErrorMessage, @originalMessage);
250 | THROW 50000, @ErrorMessage, @ErrorSeverity;
251 | END
252 | GO
253 |
254 |
255 | BEGIN TRY
256 | INSERT Music.Album(AlbumId, Name, ArtistId, CatalogNumber, PublisherId)
257 | VALUES (5,'who are you',2,'badnumber',2);
258 | END TRY
259 | BEGIN CATCH
260 | EXEC ErrorHandling.ErrorMap$MapError;
261 | END CATCH
262 |
263 | ----DML Triggers
264 | -----AFTER Triggers
265 | -------Range Checks on Multiple Rows
266 | CREATE SCHEMA Accounting;
267 | GO
268 | CREATE TABLE Accounting.Account
269 | (
270 | AccountNumber char(10) NOT NULL
271 | CONSTRAINT PKAccount PRIMARY KEY
272 | --would have other columns
273 | );
274 |
275 | CREATE TABLE Accounting.AccountActivity
276 | (
277 | AccountNumber char(10) NOT NULL
278 | CONSTRAINT FKAccount$has$Accounting_AccountActivity
279 | FOREIGN KEY REFERENCES Accounting.Account(AccountNumber),
280 | --this might be a value that each ATM/Teller generates
281 | TransactionNumber char(20) NOT NULL,
282 | Date datetime2(3) NOT NULL,
283 | TransactionAmount numeric(12,2) NOT NULL,
284 | CONSTRAINT PKAccountActivity
285 | PRIMARY KEY (AccountNumber, TransactionNumber)
286 | );
287 | GO
288 |
289 |
290 | CREATE TRIGGER Accounting.AccountActivity$insertTrigger
291 | ON Accounting.AccountActivity
292 | AFTER INSERT AS
293 | BEGIN
294 | SET NOCOUNT ON;
295 | SET ROWCOUNT 0; --in case the client has modified the rowcount
296 | --use inserted for insert or update trigger, deleted for update or delete trigger
297 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
298 | --that is equal to number of merged rows, not rows being checked in trigger
299 | DECLARE @msg varchar(2000), --used to hold the error message
300 | --use inserted for insert or update trigger, deleted for update or delete trigger
301 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
302 | --that is equal to number of merged rows, not rows being checked in trigger
303 | @rowsAffected int = (SELECT COUNT(*) FROM inserted);
304 | -- @rowsAffected int = (SELECT COUNT(*) FROM deleted);
305 |
306 | --no need to continue on if no rows affected
307 | IF @rowsAffected = 0 RETURN;
308 |
309 | BEGIN TRY
310 |
311 | --[validation section]
312 | --disallow Transactions that would put balance into negatives
313 | IF EXISTS ( SELECT AccountNumber
314 | FROM Accounting.AccountActivity AS AccountActivity
315 | WHERE EXISTS (SELECT *
316 | FROM inserted
317 | WHERE inserted.AccountNumber =
318 | AccountActivity.AccountNumber)
319 | GROUP BY AccountNumber
320 | HAVING SUM(TransactionAmount) < 0)
321 | BEGIN
322 | IF @rowsAffected = 1
323 | SELECT @msg = CONCAT('Account: ', AccountNumber,
324 | ' TransactionNumber:',TransactionNumber, ' for amount: ', TransactionAmount,
325 | ' cannot be processed as it will cause a negative balance')
326 | FROM inserted;
327 | ELSE
328 | SELECT @msg = 'One of the rows caused a negative balance';
329 | THROW 50000, @msg, 16;
330 | END
331 |
332 | --[modification section]
333 | END TRY
334 | BEGIN CATCH
335 | IF @@trancount > 0
336 | ROLLBACK TRANSACTION;
337 |
338 | THROW; --will halt the batch or be caught by the caller's catch block
339 |
340 | END CATCH
341 | END;
342 | GO
343 |
344 | SELECT AccountNumber
345 | FROM Accounting.AccountActivity AS AccountActivity
346 | GROUP BY AccountNumber
347 | HAVING SUM(TransactionAmount) < 0;
348 | GO
349 |
350 |
351 | --create some set up test data
352 | INSERT INTO Accounting.Account(AccountNumber)
353 | VALUES ('1111111111');
354 |
355 | INSERT INTO Accounting.AccountActivity(AccountNumber, TransactionNumber,
356 | Date, TransactionAmount)
357 | VALUES ('1111111111','A0000000000000000001','20050712',100),
358 | ('1111111111','A0000000000000000002','20050713',100);
359 | GO
360 |
361 | INSERT INTO Accounting.AccountActivity(AccountNumber, TransactionNumber,
362 | Date, TransactionAmount)
363 | VALUES ('1111111111','A0000000000000000003','20050713',-300);
364 | INSERT INTO Accounting.Account(AccountNumber)
365 | VALUES ('2222222222');
366 | GO
367 |
368 | --Now, this data will violate the constraint for the new Account:
369 | INSERT INTO Accounting.AccountActivity(AccountNumber, TransactionNumber,
370 | Date, TransactionAmount)
371 | VALUES ('1111111111','A0000000000000000004','20050714',100),
372 | ('2222222222','A0000000000000000005','20050715',100),
373 | ('2222222222','A0000000000000000006','20050715',100),
374 | ('2222222222','A0000000000000000007','20050715',-201);
375 | GO
376 |
377 | SELECT trigger_events.type_desc
378 | FROM sys.trigger_events
379 | JOIN sys.triggers
380 | ON sys.triggers.object_id = sys.trigger_events.object_id
381 | WHERE triggers.name = 'AccountActivity$insertTrigger';
382 | GO
383 |
384 |
385 | ALTER TABLE Accounting.Account
386 | ADD BalanceAmount numeric(12,2) NOT NULL
387 | CONSTRAINT DFLTAccount_BalanceAmount DEFAULT (0.00);
388 | GO
389 |
390 | SELECT Account.AccountNumber,
391 | SUM(COALESCE(AccountActivity.TransactionAmount,0.00)) AS NewBalance
392 | FROM Accounting.Account
393 | LEFT OUTER JOIN Accounting.AccountActivity
394 | ON Account.AccountNumber = AccountActivity.AccountNumber
395 | GROUP BY Account.AccountNumber;
396 | GO
397 |
398 | WITH UpdateCTE AS (
399 | SELECT Account.AccountNumber,
400 | SUM(coalesce(TransactionAmount,0.00)) AS NewBalance
401 | FROM Accounting.Account
402 | LEFT OUTER JOIN Accounting.AccountActivity
403 | On Account.AccountNumber = AccountActivity.AccountNumber
404 | GROUP BY Account.AccountNumber)
405 | UPDATE Account
406 | SET BalanceAmount = UpdateCTE.NewBalance
407 | FROM Accounting.Account
408 | JOIN UpdateCTE
409 | ON Account.AccountNumber = UpdateCTE.AccountNumber;
410 | GO
411 |
412 |
413 | ALTER TRIGGER Accounting.AccountActivity$insertTrigger
414 | ON Accounting.AccountActivity
415 | AFTER INSERT AS
416 | BEGIN
417 | SET NOCOUNT ON;
418 | SET ROWCOUNT 0; --in case the client has modified the rowcount
419 | --use inserted for insert or update trigger, deleted for update or delete trigger
420 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
421 | --that is equal to number of merged rows, not rows being checked in trigger
422 | DECLARE @msg varchar(2000), --used to hold the error message
423 | --use inserted for insert or update trigger, deleted for update or delete trigger
424 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
425 | --that is equal to number of merged rows, not rows being checked in trigger
426 | @rowsAffected int = (SELECT COUNT(*) FROM inserted);
427 | -- @rowsAffected int = (SELECT COUNT(*) FROM deleted);
428 |
429 | BEGIN TRY
430 |
431 | --[validation section]
432 | --disallow Transactions that would put balance into negatives
433 | IF EXISTS ( SELECT AccountNumber
434 | FROM Accounting.AccountActivity as AccountActivity
435 | WHERE EXISTS (SELECT *
436 | FROM inserted
437 | WHERE inserted.AccountNumber =
438 | AccountActivity.AccountNumber)
439 | GROUP BY AccountNumber
440 | HAVING SUM(TransactionAmount) < 0)
441 | BEGIN
442 | IF @rowsAffected = 1
443 | SELECT @msg = 'Account: ' + AccountNumber +
444 | ' TransactionNumber:' +
445 | cast(TransactionNumber as varchar(36)) +
446 | ' for amount: ' + cast(TransactionAmount as varchar(10))+
447 | ' cannot be processed as it will cause a negative balance'
448 | FROM inserted;
449 | ELSE
450 | SELECT @msg = 'One of the rows caused a negative balance';
451 |
452 | THROW 50000, @msg, 16;
453 | END;
454 |
455 | --[modification section]
456 | IF UPDATE (TransactionAmount)
457 | BEGIN
458 | ;WITH Updater as (
459 | SELECT Account.AccountNumber,
460 | SUM(coalesce(TransactionAmount,0.00)) AS NewBalance
461 | FROM Accounting.Account
462 | LEFT OUTER JOIN Accounting.AccountActivity
463 | On Account.AccountNumber = AccountActivity.AccountNumber
464 | --This where clause limits the summarizations to those rows
465 | --that were modified by the DML statement that caused
466 | --this trigger to fire.
467 | WHERE EXISTS (SELECT *
468 | FROM Inserted
469 | WHERE Account.AccountNumber = Inserted.AccountNumber)
470 | GROUP BY Account.AccountNumber)
471 |
472 | UPDATE Account
473 | SET BalanceAmount = Updater.NewBalance
474 | FROM Accounting.Account
475 | JOIN Updater
476 | ON Account.AccountNumber = Updater.AccountNumber;
477 | END;
478 |
479 |
480 | END TRY
481 | BEGIN CATCH
482 | IF @@trancount > 0
483 | ROLLBACK TRANSACTION;
484 |
485 | THROW; --will halt the batch or be caught by the caller's catch block
486 |
487 | END CATCH;
488 | END;
489 | GO
490 |
491 | INSERT INTO Accounting.AccountActivity(AccountNumber, TransactionNumber,
492 | Date, TransactionAmount)
493 | VALUES ('1111111111','A0000000000000000004','20050714',100);
494 | GO
495 |
496 | SELECT Account.AccountNumber,Account.BalanceAmount,
497 | SUM(coalesce(AccountActivity.TransactionAmount,0.00)) AS SummedBalance
498 | FROM Accounting.Account
499 | LEFT OUTER JOIN Accounting.AccountActivity
500 | ON Account.AccountNumber = AccountActivity.AccountNumber
501 | GROUP BY Account.AccountNumber,Account.BalanceAmount;
502 | GO
503 |
504 |
505 | INSERT into Accounting.AccountActivity(AccountNumber, TransactionNumber,
506 | Date, TransactionAmount)
507 | VALUES ('1111111111','A0000000000000000005','20050714',100),
508 | ('2222222222','A0000000000000000006','20050715',100),
509 | ('2222222222','A0000000000000000007','20050715',100);
510 |
511 | ----Cascading Inserts
512 |
513 | CREATE SCHEMA Internet;
514 | GO
515 | CREATE TABLE Internet.Url
516 | (
517 | UrlId int NOT NULL IDENTITY(1,1) CONSTRAINT PKUrl primary key,
518 | Name varchar(60) NOT NULL CONSTRAINT AKUrl_Name UNIQUE,
519 | Url varchar(200) NOT NULL CONSTRAINT AKUrl_Url UNIQUE
520 | );
521 | GO
522 |
523 | --Not a user manageable table, so not using identity key (as discussed in
524 | --Chapter 6 when I discussed choosing keys) in this one table. Others are
525 | --using identity-based keys in this example.
526 | CREATE TABLE Internet.UrlStatusType
527 | (
528 | UrlStatusTypeId int NOT NULL
529 | CONSTRAINT PKUrlStatusType PRIMARY KEY,
530 | Name varchar(20) NOT NULL
531 | CONSTRAINT AKUrlStatusType UNIQUE,
532 | DefaultFlag bit NOT NULL,
533 | DisplayOnSiteFlag bit NOT NULL
534 | );
535 |
536 | CREATE TABLE Internet.UrlStatus
537 | (
538 | UrlStatusId int NOT NULL IDENTITY(1,1)
539 | CONSTRAINT PKUrlStatus PRIMARY KEY,
540 | UrlStatusTypeId int NOT NULL
541 | CONSTRAINT
542 | FKUrlStatusType$defines_status_type_of$Internet_UrlStatus
543 | REFERENCES Internet.UrlStatusType(UrlStatusTypeId),
544 | UrlId int NOT NULL
545 | CONSTRAINT FKUrl$has_status_history_in$Internet_UrlStatus
546 | REFERENCES Internet.Url(UrlId),
547 | ActiveTime datetime2(3),
548 | CONSTRAINT AKUrlStatus_statusUrlDate
549 | UNIQUE (UrlStatusTypeId, UrlId, ActiveTime)
550 | );
551 |
552 | --set up status types
553 | INSERT Internet.UrlStatusType (UrlStatusTypeId, Name,
554 | DefaultFlag, DisplayOnSiteFlag)
555 | VALUES (1, 'Unverified',1,0),
556 | (2, 'Verified',0,1),
557 | (3, 'Unable to locate',0,0);
558 | GO
559 |
560 | CREATE TRIGGER Internet.Url$insertTrigger
561 | ON Internet.Url
562 | AFTER INSERT AS
563 | BEGIN
564 |
565 | SET NOCOUNT ON;
566 | SET ROWCOUNT 0; --in case the client has modified the rowcount
567 | --use inserted for insert or update trigger, deleted for update or delete trigger
568 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
569 | --that is equal to number of merged rows, not rows being checked in trigger
570 | DECLARE @msg varchar(2000), --used to hold the error message
571 | --use inserted for insert or update trigger, deleted for update or delete trigger
572 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
573 | --that is equal to number of merged rows, not rows being checked in trigger
574 | @rowsAffected int = (SELECT COUNT(*) FROM inserted);
575 | -- @rowsAffected int = (SELECT COUNT(*) FROM deleted);
576 |
577 | BEGIN TRY
578 | --[validation section]
579 |
580 | --[modification section]
581 | --add a row to the UrlStatus table to tell it that the new row
582 | --should start out as the default status
583 | INSERT INTO Internet.UrlStatus (UrlId, UrlStatusTypeId, ActiveTime)
584 | SELECT inserted.UrlId, UrlStatusType.UrlStatusTypeId,
585 | SYSDATETIME()
586 | FROM inserted
587 | CROSS JOIN (SELECT UrlStatusTypeId
588 | FROM UrlStatusType
589 | WHERE DefaultFlag = 1) as UrlStatusType;
590 | --use cross join to apply this one row to
591 | --rows in inserted
592 | END TRY
593 | BEGIN CATCH
594 | IF @@TRANCOUNT > 0
595 | ROLLBACK TRANSACTION;
596 | THROW; --will halt the batch or be caught by the caller's catch block
597 |
598 | END CATCH;
599 | END;
600 | GO
601 |
602 |
603 | INSERT Internet.Url(Name, Url)
604 | VALUES ('Author''s Website',
605 | 'http://drsql.org');
606 | GO
607 |
608 |
609 |
610 | SELECT Url.Url,Url.Name,UrlStatusType.Name as Status, UrlStatus.ActiveTime
611 | FROM Internet.Url
612 | JOIN Internet.UrlStatus
613 | ON Url.UrlId = UrlStatus.UrlId
614 | JOIN Internet.UrlStatusType
615 | ON UrlStatusType.UrlStatusTypeId = UrlStatus.UrlStatusTypeId;
616 |
617 |
618 | -----Cascading from Child to Parent
619 |
620 | CREATE SCHEMA Entertainment;
621 | GO
622 | CREATE TABLE Entertainment.GamePlatform
623 | (
624 | GamePlatformId int NOT NULL CONSTRAINT PKGamePlatform PRIMARY KEY,
625 | Name varchar(50) NOT NULL CONSTRAINT AKGamePlatform_Name UNIQUE
626 | );
627 | CREATE TABLE Entertainment.Game
628 | (
629 | GameId int NOT NULL CONSTRAINT PKGame PRIMARY KEY,
630 | Name varchar(50) NOT NULL CONSTRAINT AKGame_Name UNIQUE
631 | --more details that are common to all platforms
632 | );
633 |
634 | --associative entity with cascade relationships back to Game and GamePlatform
635 | CREATE TABLE Entertainment.GameInstance
636 | (
637 | GamePlatformId int NOT NULL,
638 | GameId int NOT NULL,
639 | PurchaseDate date NOT NULL,
640 | CONSTRAINT PKGameInstance PRIMARY KEY (GamePlatformId, GameId),
641 | CONSTRAINT FKGame$is_owned_on_platform_by$EntertainmentGameInstance
642 | FOREIGN KEY (GameId)
643 | REFERENCES Entertainment.Game(GameId) ON DELETE CASCADE,
644 | CONSTRAINT FKGamePlatform$is_linked_to$EntertainmentGameInstance
645 | FOREIGN KEY (GamePlatformId)
646 | REFERENCES Entertainment.GamePlatform(GamePlatformId)
647 | ON DELETE CASCADE
648 | );
649 | GO
650 |
651 | INSERT Entertainment.Game (GameId, Name)
652 | VALUES (1,'Disney Infinity'),
653 | (2,'Super Mario Bros');
654 |
655 | INSERT Entertainment.GamePlatform(GamePlatformId, Name)
656 | VALUES (1,'Nintendo WiiU'), --Yes, as a matter of fact I am still a
657 | (2,'Nintendo 3DS'); --Nintendo Fanboy, why do you ask?
658 |
659 | INSERT Entertainment.GameInstance(GamePlatformId, GameId, PurchaseDate)
660 | VALUES (1,1,'20140804'),
661 | (1,2,'20140810'),
662 | (2,2,'20150604');
663 |
664 | --the full outer joins ensure that all rows are returned from all sets, leaving
665 | --nulls where data is missing
666 | SELECT GamePlatform.Name as Platform, Game.Name as Game, GameInstance. PurchaseDate
667 | FROM Entertainment.Game as Game
668 | FULL OUTER JOIN Entertainment.GameInstance as GameInstance
669 | ON Game.GameId = GameInstance.GameId
670 | FULL OUTER JOIN Entertainment.GamePlatform
671 | ON GamePlatform.GamePlatformId = GameInstance.GamePlatformId;
672 | GO
673 |
674 | CREATE TRIGGER Entertainment.GameInstance$deleteTrigger
675 | ON Entertainment.GameInstance
676 | AFTER DELETE AS
677 | BEGIN
678 |
679 | SET NOCOUNT ON;
680 | SET ROWCOUNT 0; --in case the client has modified the rowcount
681 | --use inserted for insert or update trigger, deleted for update or delete trigger
682 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
683 | --that is equal to number of merged rows, not rows being checked in trigger
684 | DECLARE @msg varchar(2000), --used to hold the error message
685 | --use inserted for insert or update trigger, deleted for update or delete trigger
686 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
687 | --that is equal to number of merged rows, not rows being checked in trigger
688 | -- @rowsAffected int = (SELECT COUNT(*) FROM inserted);
689 | @rowsAffected int = (SELECT COUNT(*) FROM deleted);
690 |
691 | BEGIN TRY
692 | --[validation section]
693 |
694 | --[modification section]
695 | --delete all Games
696 | DELETE Game --where the GameInstance was deleted
697 | WHERE GameId IN (SELECT deleted.GameId
698 | FROM deleted --and there are no GameInstances left
699 | WHERE NOT EXISTS (SELECT *
700 | FROM GameInstance
701 | WHERE GameInstance.GameId =
702 | deleted.GameId));
703 | END TRY
704 | BEGIN CATCH
705 | IF @@TRANCOUNT > 0
706 | ROLLBACK TRANSACTION;
707 | THROW; --will halt the batch or be caught by the caller's catch block
708 |
709 | END CATCH;
710 | END;
711 | DELETE Entertainment.GameInstance
712 | WHERE GamePlatformId = 1;
713 | GO
714 |
715 | SELECT GamePlatform.Name AS Platform, Game.Name AS Game, GameInstance. PurchaseDate
716 | FROM Entertainment.Game AS Game
717 | FULL OUTER JOIN Entertainment.GameInstance as GameInstance
718 | ON Game.GameId = GameInstance.GameId
719 | FULL OUTER JOIN Entertainment.GamePlatform
720 | ON GamePlatform.GamePlatformId = GameInstance.GamePlatformId;
721 | GO
722 |
723 | -----INSTEAD OF Triggers
724 | ---Redirecting Invalid Data to an Exception Table
725 | CREATE SCHEMA Measurements;
726 | GO
727 | CREATE TABLE Measurements.WeatherReading
728 | (
729 | WeatherReadingId int NOT NULL IDENTITY
730 | CONSTRAINT PKWeatherReading PRIMARY KEY,
731 | ReadingTime datetime2(3) NOT NULL
732 | CONSTRAINT AKWeatherReading_Date UNIQUE,
733 | Temperature float NOT NULL
734 | CONSTRAINT CHKWeatherReading_Temperature
735 | CHECK(Temperature BETWEEN -80 and 150)
736 | --raised from last edition for global warming
737 | );
738 | GO
739 |
740 |
741 | INSERT INTO Measurements.WeatherReading (ReadingTime, Temperature)
742 | VALUES ('20160101 0:00',82.00), ('20160101 0:01',89.22),
743 | ('20160101 0:02',600.32),('20160101 0:03',88.22),
744 | ('20160101 0:04',99.01);
745 | GO
746 |
747 | CREATE TABLE Measurements.WeatherReading_exception
748 | (
749 | WeatherReadingId int NOT NULL IDENTITY,
750 | CONSTRAINT PKWeatherReading_exception PRIMARY KEY
751 | ReadingTime datetime2(3) NOT NULL,
752 | Temperature float NULL
753 | );
754 | GO
755 |
756 |
757 | CREATE TRIGGER Measurements.WeatherReading$InsteadOfInsertTrigger
758 | ON Measurements.WeatherReading
759 | INSTEAD OF INSERT AS
760 | BEGIN
761 | SET NOCOUNT ON;
762 | SET ROWCOUNT 0; --in case the client has modified the rowcount
763 | --use inserted for insert or update trigger, deleted for update or delete trigger
764 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
765 | --that is equal to number of merged rows, not rows being checked in trigger
766 | DECLARE @msg varchar(2000), --used to hold the error message
767 | --use inserted for insert or update trigger, deleted for update or delete trigger
768 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
769 | --that is equal to number of merged rows, not rows being checked in trigger
770 | @rowsAffected int = (SELECT COUNT(*) FROM inserted);
771 | -- @rowsAffected int = (SELECT COUNT(*) FROM deleted);
772 |
773 | BEGIN TRY
774 | --[validation section]
775 | --[modification section]
776 |
777 | --
778 |
779 | --BAD data
780 | INSERT Measurements.WeatherReading_exception (ReadingTime, Temperature)
781 | SELECT ReadingTime, Temperature
782 | FROM inserted
783 | WHERE NOT(Temperature BETWEEN -80 and 150);
784 |
785 | --GOOD data
786 | INSERT Measurements.WeatherReading (ReadingTime, Temperature)
787 | SELECT ReadingTime, Temperature
788 | FROM inserted
789 | WHERE (Temperature BETWEEN -80 and 150);
790 | END TRY
791 | BEGIN CATCH
792 | IF @@trancount > 0
793 | ROLLBACK TRANSACTION;
794 |
795 | THROW; --will halt the batch or be caught by the caller's catch block
796 |
797 | END CATCH
798 | END;
799 | GO
800 |
801 |
802 | INSERT INTO Measurements.WeatherReading (ReadingTime, Temperature)
803 | VALUES ('20160101 0:00',82.00), ('20160101 0:01',89.22),
804 | ('20160101 0:02',600.32),('20160101 0:03',88.22),
805 | ('20160101 0:04',99.01);
806 |
807 | SELECT *
808 | FROM Measurements.WeatherReading;
809 | GO
810 | SELECT *
811 | FROM Measurements.WeatherReading_exception;
812 | GO
813 |
814 | SELECT SCOPE_IDENTITY();
815 | GO
816 |
817 | ---Forcing No Action to Be Performed on a Table
818 |
819 | CREATE SCHEMA System;
820 | GO
821 | CREATE TABLE System.Version
822 | (
823 | DatabaseVersion varchar(10)
824 | );
825 | INSERT INTO System.Version (DatabaseVersion)
826 | VALUES ('1.0.12');
827 | GO
828 |
829 |
830 | CREATE TRIGGER System.Version$InsteadOfInsertUpdateDeleteTrigger
831 | ON System.Version
832 | INSTEAD OF INSERT, UPDATE, DELETE AS
833 | BEGIN
834 | SET NOCOUNT ON;
835 | SET ROWCOUNT 0; --in case the client has modified the rowcount
836 | --use inserted for insert or update trigger, deleted for update or delete trigger
837 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
838 | --that is equal to number of merged rows, not rows being checked in trigger
839 | DECLARE @msg varchar(2000), --used to hold the error message
840 | --use inserted for insert or update trigger, deleted for update or delete trigger
841 | --count instead of @@rowcount due to merge behavior that sets @@rowcount to a number
842 | --that is equal to number of merged rows, not rows being checked in trigger
843 | @rowsAffected int = (SELECT COUNT(*) FROM inserted);
844 |
845 | IF @rowsAffected = 0 SET @rowsAffected = (SELECT COUNT(*) FROM deleted);
846 |
847 | --no need to complain if no rows affected
848 | IF @rowsAffected = 0 RETURN;
849 |
850 | --No error handling necessary, just the message.
851 | --We just put the kibosh on the action.
852 | THROW 50000, 'The System.Version table may not be modified in production', 16;
853 | END;
854 | GO
855 |
856 |
857 | UPDATE System.Version
858 | SET DatabaseVersion = '1.1.1';
859 | GO
860 | SELECT *
861 | FROM System.Version;
862 | GO
863 |
864 | Returns:
865 | ALTER TABLE system.version
866 | DISABLE TRIGGER version$InsteadOfInsertUpdateDeleteTrigger;
867 | GO
868 | UPDATE System.Version
869 | SET DatabaseVersion = '1.1.1';
870 | GO
871 |
872 | SELECT *
873 | FROM System.Version;
874 | GO
875 |
876 | ALTER TABLE System.Version
877 | ENABLE TRIGGER Version$InsteadOfInsertUpdateDeleteTrigger;
878 | GO
879 |
880 | ----Dealing with Trigger and Constraint Errors
881 | CREATE SCHEMA alt;
882 | GO
883 | CREATE TABLE alt.errorHandlingTest
884 | (
885 | errorHandlingTestId int CONSTRAINT PKerrorHandlingTest PRIMARY KEY,
886 | CONSTRAINT CHKerrorHandlingTest_errorHandlingTestId_greaterThanZero
887 | CHECK (errorHandlingTestId > 0)
888 | );
889 | GO
890 |
891 | CREATE TRIGGER alt.errorHandlingTest$insertTrigger
892 | ON alt.errorHandlingTest
893 | AFTER INSERT
894 | AS
895 | BEGIN TRY
896 | THROW 50000, 'Test Error',16;
897 | END TRY
898 | BEGIN CATCH
899 | IF @@TRANCOUNT > 0
900 | ROLLBACK TRANSACTION;
901 | THROW;
902 | END CATCH;
903 | GO
904 |
905 |
906 | --NO Transaction, Constraint Error
907 | INSERT alt.errorHandlingTest
908 | VALUES (-1);
909 | SELECT 'continues';
910 | GO
911 |
912 | INSERT alt.errorHandlingTest
913 | VALUES (1);
914 | SELECT 'continues';
915 | GO
916 |
917 | BEGIN TRY
918 | BEGIN TRANSACTION
919 | INSERT alt.errorHandlingTest
920 | VALUES (-1);
921 | COMMIT;
922 | END TRY
923 | BEGIN CATCH
924 | SELECT CASE XACT_STATE()
925 | WHEN 1 THEN 'Committable'
926 | WHEN 0 THEN 'No transaction'
927 | ELSE 'Uncommitable tran' END as XACT_STATE
928 | ,ERROR_NUMBER() AS ErrorNumber
929 | ,ERROR_MESSAGE() as ErrorMessage;
930 | IF @@TRANCOUNT > 0
931 | ROLLBACK TRANSACTION;
932 | END CATCH;
933 | GO
934 |
935 |
936 | BEGIN TRANSACTION
937 | BEGIN TRY
938 | INSERT alt.errorHandlingTest
939 | VALUES (1);
940 | COMMIT TRANSACTION;
941 | END TRY
942 | BEGIN CATCH
943 | SELECT CASE XACT_STATE()
944 | WHEN 1 THEN 'Committable'
945 | WHEN 0 THEN 'No transaction'
946 | ELSE 'Uncommitable tran' END as XACT_STATE
947 | ,ERROR_NUMBER() AS ErrorNumber
948 | ,ERROR_MESSAGE() as ErrorMessage;
949 | IF @@TRANCOUNT > 0
950 | ROLLBACK TRANSACTION;
951 | END CATCH;
952 | GO
953 |
954 | ALTER TRIGGER alt.errorHandlingTest$insertTrigger
955 | ON alt.errorHandlingTest
956 | AFTER INSERT
957 | AS
958 | BEGIN TRY
959 | THROW 50000, 'Test Error',16;
960 | END TRY
961 | BEGIN CATCH
962 | --Commented out for test purposes
963 | --IF @@TRANCOUNT > 0
964 | -- ROLLBACK TRANSACTION;
965 |
966 | THROW;
967 | END CATCH;
968 | BEGIN TRY
969 | BEGIN TRANSACTION
970 | INSERT alt.errorHandlingTest
971 | VALUES (1);
972 | COMMIT TRANSACTION;
973 | END TRY
974 | GO
975 |
976 |
977 | BEGIN CATCH
978 | SELECT CASE XACT_STATE()
979 | WHEN 1 THEN 'Committable'
980 | WHEN 0 THEN 'No transaction'
981 | ELSE 'Uncommitable tran' END as XACT_STATE
982 | ,ERROR_NUMBER() AS ErrorNumber
983 | ,ERROR_MESSAGE() as ErrorMessage;
984 | IF @@TRANCOUNT > 0
985 | ROLLBACK TRANSACTION;
986 | END CATCH;
987 | BEGIN TRY
988 | BEGIN TRANSACTION;
989 | DECLARE @errorMessage nvarchar(4000) = 'Error inserting data into alt.errorHandlingTest';
990 | INSERT alt.errorHandlingTest
991 | VALUES (-1);
992 | COMMIT TRANSACTION;
993 | END TRY
994 | BEGIN CATCH
995 | IF @@TRANCOUNT > 0
996 | ROLLBACK TRANSACTION;
997 |
998 | --I also add in the stored procedure or trigger where the error
999 | --occurred also when in a coded object
1000 | SET @errorMessage = CONCAT( COALESCE(@errorMessage,''), ' ( System Error: ',
1001 | ERROR_NUMBER(),':',ERROR_MESSAGE(),
1002 | ' : Line Number:',ERROR_LINE());
1003 | THROW 50000,@errorMessage,16;
1004 | END CATCH;
1005 | GO
1006 |
--------------------------------------------------------------------------------