From 47c370fb52de1b39dab0f8b0e0f4b8d8b0bf8b11 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Sep 2024 08:42:57 -0700 Subject: [PATCH 001/111] Raw resources in the Lake and Resource Id integer map --- .../Features/Schema/Migrations/84.sql | 5583 +++++++++++++++++ .../Features/Schema/SchemaVersion.cs | 2 + .../Features/Schema/SchemaVersionConstants.cs | 4 +- .../Features/Schema/Sql/Scripts/Sequences.sql | 9 + .../TransactionCheckWithInitialiScript.sql | 2 +- .../Sql/Sprocs/AssignResourceIdInts.sql | 29 + .../Schema/Sql/Sprocs/GetResourceVersions.sql | 2 + .../Schema/Sql/Sprocs/GetResources.sql | 28 +- .../Sprocs/GetResourcesByTransactionId.sql | 2 + .../GetResourcesByTypeAndSurrogateIdRange.sql | 4 +- .../Schema/Sql/Sprocs/HardDeleteResource.sql | 2 +- .../Schema/Sql/Sprocs/MergeResources.sql | 161 +- .../Sql/Sprocs/UpdateResourceSearchParams.sql | 9 +- .../Sql/Tables/ReferenceSearchParam.sql | 39 +- .../Features/Schema/Sql/Tables/Resource.sql | 73 +- .../Schema/Sql/Tables/ResourceIdIntMap.sql | 11 + .../Schema/Sql/Types/ResourceList.sql | 3 +- .../Schema/Sql/Views/ReferenceSearchParam.sql | 54 + .../Features/Schema/Sql/Views/Resource.sql | 89 + .../QueryGenerators/SqlQueryGenerator.cs | 3 + .../Features/Search/SqlServerSearchService.cs | 33 +- .../Storage/SqlRetry/ISqlRetryService.cs | 2 + .../Storage/SqlRetry/SqlRetryService.cs | 9 + .../Features/Storage/SqlSecondaryStore.cs | 113 + .../Storage/SqlServerFhirDataStore.cs | 69 +- .../Features/Storage/SqlServerFhirModel.cs | 14 +- .../Features/Storage/SqlStoreClient.cs | 56 +- .../Merge/MergeResourceWrapper.cs | 5 + .../Merge/ResourceListRowGenerator.cs | 2 +- .../Microsoft.Health.Fhir.SqlServer.csproj | 3 +- .../Persistence/FhirStorageTests.cs | 11 +- .../SqlServerFhirStorageTestHelper.cs | 34 +- .../Persistence/SqlServerWatchdogTests.cs | 4 +- 33 files changed, 6313 insertions(+), 151 deletions(-) create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/AssignResourceIdInts.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlSecondaryStore.cs diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql new file mode 100644 index 0000000000..9c1104fa7d --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -0,0 +1,5583 @@ + +/************************************************************************************************* + Auto-Generated from Sql build task. Do not manually edit it. +**************************************************************************************************/ +SET XACT_ABORT ON +BEGIN TRAN +IF EXISTS (SELECT * + FROM sys.tables + WHERE name = 'ClaimType') + BEGIN + ROLLBACK; + RETURN; + END + + +GO +INSERT INTO dbo.SchemaVersion +VALUES (84, 'started'); + +CREATE PARTITION FUNCTION PartitionFunction_ResourceTypeId(SMALLINT) + AS RANGE RIGHT + FOR VALUES (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150); + +CREATE PARTITION SCHEME PartitionScheme_ResourceTypeId + AS PARTITION PartitionFunction_ResourceTypeId + ALL TO ([PRIMARY]); + + +GO +CREATE PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp(DATETIME2 (7)) + AS RANGE RIGHT + FOR VALUES (N'1970-01-01T00:00:00.0000000'); + +CREATE PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp + AS PARTITION PartitionFunction_ResourceChangeData_Timestamp + ALL TO ([PRIMARY]); + +DECLARE @numberOfHistoryPartitions AS INT = 48; + +DECLARE @numberOfFuturePartitions AS INT = 720; + +DECLARE @rightPartitionBoundary AS DATETIME2 (7); + +DECLARE @currentDateTime AS DATETIME2 (7) = sysutcdatetime(); + +WHILE @numberOfHistoryPartitions >= -@numberOfFuturePartitions + BEGIN + SET @rightPartitionBoundary = DATEADD(hour, DATEDIFF(hour, 0, @currentDateTime) - @numberOfHistoryPartitions, 0); + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [Primary]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@rightPartitionBoundary); + SET @numberOfHistoryPartitions -= 1; + END + +CREATE SEQUENCE dbo.ResourceSurrogateIdUniquifierSequence + AS INT + START WITH 0 + INCREMENT BY 1 + MINVALUE 0 + MAXVALUE 79999 + CYCLE + CACHE 1000000; + + +GO +CREATE SEQUENCE dbo.ResourceIdIntMapSequence + AS INT + START WITH 0 + INCREMENT BY 1 + MINVALUE 0 + MAXVALUE 79999 + CYCLE + CACHE 1000000; + +CREATE TYPE dbo.BigintList AS TABLE ( + Id BIGINT NOT NULL PRIMARY KEY); + +CREATE TYPE dbo.DateTimeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + StartDateTime DATETIMEOFFSET (7) NOT NULL, + EndDateTime DATETIMEOFFSET (7) NOT NULL, + IsLongerThanADay BIT NOT NULL, + IsMin BIT NOT NULL, + IsMax BIT NOT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax)); + +CREATE TYPE dbo.NumberSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NULL, + HighValue DECIMAL (36, 18) NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue)); + +CREATE TYPE dbo.QuantitySearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + QuantityCodeId INT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NULL, + HighValue DECIMAL (36, 18) NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue)); + +CREATE TYPE dbo.ReferenceSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId)); + +CREATE TYPE dbo.ReferenceTokenCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri1 VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId1 SMALLINT NULL, + ReferenceResourceId1 VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion1 INT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.ResourceDateKeyList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ResourceSurrogateId BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId, ResourceSurrogateId)); + +CREATE TYPE dbo.ResourceKeyList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NULL UNIQUE (ResourceTypeId, ResourceId, Version)); + +CREATE TYPE dbo.ResourceList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + HasVersionToCompare BIT NOT NULL, + IsDeleted BIT NOT NULL, + IsHistory BIT NOT NULL, + KeepHistory BIT NOT NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + SearchParamHash VARCHAR (64) NULL, + OffsetInFile INT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), + UNIQUE (ResourceTypeId, ResourceId, Version)); + +CREATE TYPE dbo.ResourceWriteClaimList AS TABLE ( + ResourceSurrogateId BIGINT NOT NULL, + ClaimTypeId TINYINT NOT NULL, + ClaimValue NVARCHAR (128) NOT NULL); + +CREATE TYPE dbo.StringList AS TABLE ( + String VARCHAR (MAX)); + +CREATE TYPE dbo.StringSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL, + IsMin BIT NOT NULL, + IsMax BIT NOT NULL); + +CREATE TYPE dbo.TokenDateTimeCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + StartDateTime2 DATETIMEOFFSET (7) NOT NULL, + EndDateTime2 DATETIMEOFFSET (7) NOT NULL, + IsLongerThanADay2 BIT NOT NULL); + +CREATE TYPE dbo.TokenNumberNumberCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + SingleValue3 DECIMAL (36, 18) NULL, + LowValue3 DECIMAL (36, 18) NULL, + HighValue3 DECIMAL (36, 18) NULL, + HasRange BIT NOT NULL); + +CREATE TYPE dbo.TokenQuantityCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SystemId2 INT NULL, + QuantityCodeId2 INT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL); + +CREATE TYPE dbo.TokenSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + Code VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.TokenStringCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + Text2 NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow2 NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL); + +CREATE TYPE dbo.TokenTextList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (400) COLLATE Latin1_General_CI_AI NOT NULL); + +CREATE TYPE dbo.TokenTokenCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.SearchParamTableType_2 AS TABLE ( + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (20) NOT NULL, + IsPartiallySupported BIT NOT NULL); + +CREATE TYPE dbo.BulkReindexResourceTableType_1 AS TABLE ( + Offset INT NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ETag INT NULL, + SearchParamHash VARCHAR (64) NOT NULL); + +CREATE TYPE dbo.UriSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri)); + +CREATE TABLE dbo.ClaimType ( + ClaimTypeId TINYINT IDENTITY (1, 1) NOT NULL, + Name VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_ClaimType_ClaimTypeId UNIQUE (ClaimTypeId), + CONSTRAINT PKC_ClaimType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.CompartmentAssignment ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + CompartmentTypeId TINYINT NOT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + IsHistory BIT NOT NULL, + CONSTRAINT PKC_CompartmentAssignment PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId, CompartmentTypeId, ReferenceResourceId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + + +GO +ALTER TABLE dbo.CompartmentAssignment + ADD CONSTRAINT DF_CompartmentAssignment_IsHistory DEFAULT 0 FOR IsHistory; + + +GO +ALTER TABLE dbo.CompartmentAssignment SET (LOCK_ESCALATION = AUTO); + + +GO +CREATE NONCLUSTERED INDEX IX_CompartmentAssignment_CompartmentTypeId_ReferenceResourceId + ON dbo.CompartmentAssignment(ResourceTypeId, CompartmentTypeId, ReferenceResourceId, ResourceSurrogateId) WHERE IsHistory = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.CompartmentType ( + CompartmentTypeId TINYINT IDENTITY (1, 1) NOT NULL, + Name VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_CompartmentType_CompartmentTypeId UNIQUE (CompartmentTypeId), + CONSTRAINT PKC_CompartmentType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.DateTimeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + StartDateTime DATETIME2 (7) NOT NULL, + EndDateTime DATETIME2 (7) NOT NULL, + IsLongerThanADay BIT NOT NULL, + IsMin BIT CONSTRAINT date_IsMin_Constraint DEFAULT 0 NOT NULL, + IsMax BIT CONSTRAINT date_IsMax_Constraint DEFAULT 0 NOT NULL +); + +ALTER TABLE dbo.DateTimeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_DateTimeSearchParam + ON dbo.DateTimeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_StartDateTime_EndDateTime_INCLUDE_IsLongerThanADay_IsMin_IsMax + ON dbo.DateTimeSearchParam(SearchParamId, StartDateTime, EndDateTime) + INCLUDE(IsLongerThanADay, IsMin, IsMax) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_EndDateTime_StartDateTime_INCLUDE_IsLongerThanADay_IsMin_IsMax + ON dbo.DateTimeSearchParam(SearchParamId, EndDateTime, StartDateTime) + INCLUDE(IsLongerThanADay, IsMin, IsMax) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_StartDateTime_EndDateTime_INCLUDE_IsMin_IsMax_WHERE_IsLongerThanADay_1 + ON dbo.DateTimeSearchParam(SearchParamId, StartDateTime, EndDateTime) + INCLUDE(IsMin, IsMax) WHERE IsLongerThanADay = 1 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_EndDateTime_StartDateTime_INCLUDE_IsMin_IsMax_WHERE_IsLongerThanADay_1 + ON dbo.DateTimeSearchParam(SearchParamId, EndDateTime, StartDateTime) + INCLUDE(IsMin, IsMax) WHERE IsLongerThanADay = 1 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +IF NOT EXISTS (SELECT 1 + FROM sys.tables + WHERE name = 'EventAgentCheckpoint') + BEGIN + CREATE TABLE dbo.EventAgentCheckpoint ( + CheckpointId VARCHAR (64) NOT NULL, + LastProcessedDateTime DATETIMEOFFSET (7), + LastProcessedIdentifier VARCHAR (64) , + UpdatedOn DATETIME2 (7) DEFAULT sysutcdatetime() NOT NULL, + CONSTRAINT PK_EventAgentCheckpoint PRIMARY KEY CLUSTERED (CheckpointId) + ) ON [PRIMARY]; + END + +CREATE PARTITION FUNCTION EventLogPartitionFunction(TINYINT) + AS RANGE RIGHT + FOR VALUES (0, 1, 2, 3, 4, 5, 6, 7); + + +GO +CREATE PARTITION SCHEME EventLogPartitionScheme + AS PARTITION EventLogPartitionFunction + ALL TO ([PRIMARY]); + + +GO +CREATE TABLE dbo.EventLog ( + PartitionId AS isnull(CONVERT (TINYINT, EventId % 8), 0) PERSISTED, + EventId BIGINT IDENTITY (1, 1) NOT NULL, + EventDate DATETIME NOT NULL, + Process VARCHAR (100) NOT NULL, + Status VARCHAR (10) NOT NULL, + Mode VARCHAR (200) NULL, + Action VARCHAR (20) NULL, + Target VARCHAR (100) NULL, + Rows BIGINT NULL, + Milliseconds INT NULL, + EventText NVARCHAR (3500) NULL, + SPID SMALLINT NOT NULL, + HostName VARCHAR (64) NOT NULL CONSTRAINT PKC_EventLog_EventDate_EventId_PartitionId PRIMARY KEY CLUSTERED (EventDate, EventId, PartitionId) ON EventLogPartitionScheme (PartitionId) +); + +CREATE TABLE dbo.ExportJob ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Hash VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (10) NOT NULL, + HeartbeatDateTime DATETIME2 (7) NULL, + RawJobRecord VARCHAR (MAX) NOT NULL, + JobVersion ROWVERSION NOT NULL, + CONSTRAINT PKC_ExportJob PRIMARY KEY CLUSTERED (Id) +); + +CREATE UNIQUE NONCLUSTERED INDEX IX_ExportJob_Hash_Status_HeartbeatDateTime + ON dbo.ExportJob(Hash, Status, HeartbeatDateTime); + +CREATE TABLE dbo.IndexProperties ( + TableName VARCHAR (100) NOT NULL, + IndexName VARCHAR (200) NOT NULL, + PropertyName VARCHAR (100) NOT NULL, + PropertyValue VARCHAR (100) NOT NULL, + CreateDate DATETIME CONSTRAINT DF_IndexProperties_CreateDate DEFAULT getUTCdate() NOT NULL CONSTRAINT PKC_IndexProperties_TableName_IndexName_PropertyName PRIMARY KEY CLUSTERED (TableName, IndexName, PropertyName) +); + +CREATE PARTITION FUNCTION TinyintPartitionFunction(TINYINT) + AS RANGE RIGHT + FOR VALUES (0, 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150, 151, 152, 153, 154, 155, 156, 157, 158, 159, 160, 161, 162, 163, 164, 165, 166, 167, 168, 169, 170, 171, 172, 173, 174, 175, 176, 177, 178, 179, 180, 181, 182, 183, 184, 185, 186, 187, 188, 189, 190, 191, 192, 193, 194, 195, 196, 197, 198, 199, 200, 201, 202, 203, 204, 205, 206, 207, 208, 209, 210, 211, 212, 213, 214, 215, 216, 217, 218, 219, 220, 221, 222, 223, 224, 225, 226, 227, 228, 229, 230, 231, 232, 233, 234, 235, 236, 237, 238, 239, 240, 241, 242, 243, 244, 245, 246, 247, 248, 249, 250, 251, 252, 253, 254, 255); + + +GO +CREATE PARTITION SCHEME TinyintPartitionScheme + AS PARTITION TinyintPartitionFunction + ALL TO ([PRIMARY]); + + +GO +CREATE TABLE dbo.JobQueue ( + QueueType TINYINT NOT NULL, + GroupId BIGINT NOT NULL, + JobId BIGINT NOT NULL, + PartitionId AS CONVERT (TINYINT, JobId % 16) PERSISTED, + Definition VARCHAR (MAX) NOT NULL, + DefinitionHash VARBINARY (20) NOT NULL, + Version BIGINT CONSTRAINT DF_JobQueue_Version DEFAULT datediff_big(millisecond, '0001-01-01', getUTCdate()) NOT NULL, + Status TINYINT CONSTRAINT DF_JobQueue_Status DEFAULT 0 NOT NULL, + Priority TINYINT CONSTRAINT DF_JobQueue_Priority DEFAULT 100 NOT NULL, + Data BIGINT NULL, + Result VARCHAR (MAX) NULL, + CreateDate DATETIME CONSTRAINT DF_JobQueue_CreateDate DEFAULT getUTCdate() NOT NULL, + StartDate DATETIME NULL, + EndDate DATETIME NULL, + HeartbeatDate DATETIME CONSTRAINT DF_JobQueue_HeartbeatDate DEFAULT getUTCdate() NOT NULL, + Worker VARCHAR (100) NULL, + Info VARCHAR (1000) NULL, + CancelRequested BIT CONSTRAINT DF_JobQueue_CancelRequested DEFAULT 0 NOT NULL CONSTRAINT PKC_JobQueue_QueueType_PartitionId_JobId PRIMARY KEY CLUSTERED (QueueType, PartitionId, JobId) ON TinyintPartitionScheme (QueueType), + CONSTRAINT U_JobQueue_QueueType_JobId UNIQUE (QueueType, JobId) +); + + +GO +CREATE INDEX IX_QueueType_PartitionId_Status_Priority + ON dbo.JobQueue(PartitionId, Status, Priority) + ON TinyintPartitionScheme (QueueType); + + +GO +CREATE INDEX IX_QueueType_GroupId + ON dbo.JobQueue(QueueType, GroupId) + ON TinyintPartitionScheme (QueueType); + + +GO +CREATE INDEX IX_QueueType_DefinitionHash + ON dbo.JobQueue(QueueType, DefinitionHash) + ON TinyintPartitionScheme (QueueType); + +CREATE TABLE dbo.NumberSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NOT NULL, + HighValue DECIMAL (36, 18) NOT NULL +); + +ALTER TABLE dbo.NumberSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_NumberSearchParam + ON dbo.NumberSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_SingleValue_WHERE_SingleValue_NOT_NULL + ON dbo.NumberSearchParam(SearchParamId, SingleValue) WHERE SingleValue IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_LowValue_HighValue + ON dbo.NumberSearchParam(SearchParamId, LowValue, HighValue) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_HighValue_LowValue + ON dbo.NumberSearchParam(SearchParamId, HighValue, LowValue) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.Parameters ( + Id VARCHAR (100) NOT NULL, + Date DATETIME NULL, + Number FLOAT NULL, + Bigint BIGINT NULL, + Char VARCHAR (4000) NULL, + Binary VARBINARY (MAX) NULL, + UpdatedDate DATETIME NULL, + UpdatedBy NVARCHAR (255) NULL CONSTRAINT PKC_Parameters_Id PRIMARY KEY CLUSTERED (Id) WITH (IGNORE_DUP_KEY = ON) +); + + +GO +CREATE TABLE dbo.ParametersHistory ( + ChangeId INT IDENTITY (1, 1) NOT NULL, + Id VARCHAR (100) NOT NULL, + Date DATETIME NULL, + Number FLOAT NULL, + Bigint BIGINT NULL, + Char VARCHAR (4000) NULL, + Binary VARBINARY (MAX) NULL, + UpdatedDate DATETIME NULL, + UpdatedBy NVARCHAR (255) NULL +); + +CREATE TABLE dbo.QuantityCode ( + QuantityCodeId INT IDENTITY (1, 1) NOT NULL, + Value NVARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_QuantityCode_QuantityCodeId UNIQUE (QuantityCodeId), + CONSTRAINT PKC_QuantityCode PRIMARY KEY CLUSTERED (Value) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.QuantitySearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + QuantityCodeId INT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NOT NULL, + HighValue DECIMAL (36, 18) NOT NULL +); + +ALTER TABLE dbo.QuantitySearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_QuantitySearchParam + ON dbo.QuantitySearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_SingleValue_INCLUDE_SystemId_WHERE_SingleValue_NOT_NULL + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, SingleValue) + INCLUDE(SystemId) WHERE SingleValue IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_LowValue_HighValue_INCLUDE_SystemId + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, LowValue, HighValue) + INCLUDE(SystemId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_HighValue_LowValue_INCLUDE_SystemId + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, HighValue, LowValue) + INCLUDE(SystemId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReferenceSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NOT NULL, + ReferenceResourceIdInt BIGINT CONSTRAINT DF_ReferenceSearchParam_ResourceIdInt DEFAULT 0 NOT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS CONSTRAINT DF_ReferenceSearchParam_ResourceId DEFAULT '' NOT NULL, + ReferenceResourceVersion INT NULL, + CONSTRAINT CH_ReferenceSearchParam_ReferenceResourceIdInt_ReferenceResourceId CHECK (ReferenceResourceIdInt = 0 + AND ReferenceResourceId <> '' + OR ReferenceResourceIdInt <> 0 + AND ReferenceResourceId = '') +); + +ALTER TABLE dbo.ReferenceSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.ReferenceSearchParam(ResourceSurrogateId, SearchParamId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceId_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.ReferenceSearchParam(ReferenceResourceIdInt, ReferenceResourceId, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReferenceTokenCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri1 VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId1 SMALLINT NULL, + ReferenceResourceId1 VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion1 INT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.ReferenceTokenCompositeSearchParam + ADD CONSTRAINT CHK_ReferenceTokenCompositeSearchParam_CodeOverflow2 CHECK (LEN(Code2) = 256 + OR CodeOverflow2 IS NULL); + +ALTER TABLE dbo.ReferenceTokenCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_ReferenceTokenCompositeSearchParam + ON dbo.ReferenceTokenCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_ReferenceResourceId1_Code2_INCLUDE_ReferenceResourceTypeId1_BaseUri1_SystemId2 + ON dbo.ReferenceTokenCompositeSearchParam(SearchParamId, ReferenceResourceId1, Code2) + INCLUDE(ReferenceResourceTypeId1, BaseUri1, SystemId2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReindexJob ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (10) NOT NULL, + HeartbeatDateTime DATETIME2 (7) NULL, + RawJobRecord VARCHAR (MAX) NOT NULL, + JobVersion ROWVERSION NOT NULL, + CONSTRAINT PKC_ReindexJob PRIMARY KEY CLUSTERED (Id) +); + +CREATE TABLE dbo.Resource ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS CONSTRAINT DF_Resource_ResourceId DEFAULT '' NOT NULL, + ResourceIdInt BIGINT CONSTRAINT DF_Resource_ResourceIdInt DEFAULT 0 NOT NULL, + Version INT NOT NULL, + IsHistory BIT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + OffsetInFile INT NULL CONSTRAINT PKC_Resource_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_Resource_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL + OR OffsetInFile IS NOT NULL), + CONSTRAINT CH_Resource_ResourceIdInt_ResourceId CHECK (ResourceIdInt = 0 + AND ResourceId <> '' + OR ResourceIdInt <> 0 + AND ResourceId = '') +); + +ALTER TABLE dbo.Resource SET (LOCK_ESCALATION = AUTO); + +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL + ON dbo.Resource(TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL + ON dbo.Resource(HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE INDEX IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId + ON dbo.Resource(ResourceIdInt, ResourceId, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE INDEX IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0 + ON dbo.Resource(ResourceIdInt, ResourceId, ResourceTypeId) + INCLUDE(Version, IsDeleted) WHERE IsHistory = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId + ON dbo.Resource(ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 + AND IsDeleted = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ResourceChangeData ( + Id BIGINT IDENTITY (1, 1) NOT NULL, + Timestamp DATETIME2 (7) CONSTRAINT DF_ResourceChangeData_Timestamp DEFAULT sysutcdatetime() NOT NULL, + ResourceId VARCHAR (64) NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceVersion INT NOT NULL, + ResourceChangeTypeId TINYINT NOT NULL +) ON PartitionScheme_ResourceChangeData_Timestamp (Timestamp); + +CREATE CLUSTERED INDEX IXC_ResourceChangeData + ON dbo.ResourceChangeData(Id ASC) WITH (ONLINE = ON) + ON PartitionScheme_ResourceChangeData_Timestamp (Timestamp); + +CREATE TABLE dbo.ResourceChangeDataStaging ( + Id BIGINT IDENTITY (1, 1) NOT NULL, + Timestamp DATETIME2 (7) CONSTRAINT DF_ResourceChangeDataStaging_Timestamp DEFAULT sysutcdatetime() NOT NULL, + ResourceId VARCHAR (64) NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceVersion INT NOT NULL, + ResourceChangeTypeId TINYINT NOT NULL +) ON [PRIMARY]; + +CREATE CLUSTERED INDEX IXC_ResourceChangeDataStaging + ON dbo.ResourceChangeDataStaging(Id ASC, Timestamp ASC) WITH (ONLINE = ON) + ON [PRIMARY]; + +ALTER TABLE dbo.ResourceChangeDataStaging WITH CHECK + ADD CONSTRAINT CHK_ResourceChangeDataStaging_partition CHECK (Timestamp < CONVERT (DATETIME2 (7), N'9999-12-31 23:59:59.9999999')); + +ALTER TABLE dbo.ResourceChangeDataStaging CHECK CONSTRAINT CHK_ResourceChangeDataStaging_partition; + +CREATE TABLE dbo.ResourceChangeType ( + ResourceChangeTypeId TINYINT NOT NULL, + Name NVARCHAR (50) NOT NULL, + CONSTRAINT PK_ResourceChangeType PRIMARY KEY CLUSTERED (ResourceChangeTypeId), + CONSTRAINT UQ_ResourceChangeType_Name UNIQUE NONCLUSTERED (Name) +) ON [PRIMARY]; + + +GO +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (0, N'Creation'); + +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (1, N'Update'); + +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (2, N'Deletion'); + +CREATE TABLE dbo.ResourceIdIntMap ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.ResourceIdIntMap SET (LOCK_ESCALATION = AUTO); + +CREATE TABLE dbo.ResourceType ( + ResourceTypeId SMALLINT IDENTITY (1, 1) NOT NULL, + Name NVARCHAR (50) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_ResourceType_ResourceTypeId UNIQUE (ResourceTypeId), + CONSTRAINT PKC_ResourceType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.ResourceWriteClaim ( + ResourceSurrogateId BIGINT NOT NULL, + ClaimTypeId TINYINT NOT NULL, + ClaimValue NVARCHAR (128) NOT NULL +) +WITH (DATA_COMPRESSION = PAGE); + +CREATE CLUSTERED INDEX IXC_ResourceWriteClaim + ON dbo.ResourceWriteClaim(ResourceSurrogateId, ClaimTypeId); + +CREATE TABLE dbo.SchemaMigrationProgress ( + Timestamp DATETIME2 (3) DEFAULT CURRENT_TIMESTAMP, + Message NVARCHAR (MAX) +); + +CREATE TABLE dbo.SearchParam ( + SearchParamId SMALLINT IDENTITY (1, 1) NOT NULL, + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (20) NULL, + LastUpdated DATETIMEOFFSET (7) NULL, + IsPartiallySupported BIT NULL, + CONSTRAINT UQ_SearchParam_SearchParamId UNIQUE (SearchParamId), + CONSTRAINT PKC_SearchParam PRIMARY KEY CLUSTERED (Uri) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.StringSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL, + IsMin BIT CONSTRAINT string_IsMin_Constraint DEFAULT 0 NOT NULL, + IsMax BIT CONSTRAINT string_IsMax_Constraint DEFAULT 0 NOT NULL +); + +ALTER TABLE dbo.StringSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_StringSearchParam + ON dbo.StringSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Text_INCLUDE_TextOverflow_IsMin_IsMax + ON dbo.StringSearchParam(SearchParamId, Text) + INCLUDE(TextOverflow, IsMin, IsMax) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Text_INCLUDE_IsMin_IsMax_WHERE_TextOverflow_NOT_NULL + ON dbo.StringSearchParam(SearchParamId, Text) + INCLUDE(IsMin, IsMax) WHERE TextOverflow IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.System ( + SystemId INT IDENTITY (1, 1) NOT NULL, + Value NVARCHAR (256) NOT NULL, + CONSTRAINT UQ_System_SystemId UNIQUE (SystemId), + CONSTRAINT PKC_System PRIMARY KEY CLUSTERED (Value) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE [dbo].[TaskInfo] ( + [TaskId] VARCHAR (64) NOT NULL, + [QueueId] VARCHAR (64) NOT NULL, + [Status] SMALLINT NOT NULL, + [TaskTypeId] SMALLINT NOT NULL, + [RunId] VARCHAR (50) NULL, + [IsCanceled] BIT NOT NULL, + [RetryCount] SMALLINT NOT NULL, + [MaxRetryCount] SMALLINT NOT NULL, + [HeartbeatDateTime] DATETIME2 (7) NULL, + [InputData] VARCHAR (MAX) NOT NULL, + [TaskContext] VARCHAR (MAX) NULL, + [Result] VARCHAR (MAX) NULL, + [CreateDateTime] DATETIME2 (7) CONSTRAINT DF_TaskInfo_CreateDate DEFAULT SYSUTCDATETIME() NOT NULL, + [StartDateTime] DATETIME2 (7) NULL, + [EndDateTime] DATETIME2 (7) NULL, + [Worker] VARCHAR (100) NULL, + [RestartInfo] VARCHAR (MAX) NULL, + [ParentTaskId] VARCHAR (64) NULL, + CONSTRAINT PKC_TaskInfo PRIMARY KEY CLUSTERED (TaskId) WITH (DATA_COMPRESSION = PAGE) +) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; + + +GO +CREATE NONCLUSTERED INDEX IX_QueueId_Status + ON dbo.TaskInfo(QueueId, Status); + + +GO +CREATE NONCLUSTERED INDEX IX_QueueId_ParentTaskId + ON dbo.TaskInfo(QueueId, ParentTaskId); + +CREATE TABLE dbo.TokenDateTimeCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + StartDateTime2 DATETIME2 (7) NOT NULL, + EndDateTime2 DATETIME2 (7) NOT NULL, + IsLongerThanADay2 BIT NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenDateTimeCompositeSearchParam + ADD CONSTRAINT CHK_TokenDateTimeCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenDateTimeCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenDateTimeCompositeSearchParam + ON dbo.TokenDateTimeCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_StartDateTime2_EndDateTime2_INCLUDE_SystemId1_IsLongerThanADay2 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, StartDateTime2, EndDateTime2) + INCLUDE(SystemId1, IsLongerThanADay2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_EndDateTime2_StartDateTime2_INCLUDE_SystemId1_IsLongerThanADay2 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, EndDateTime2, StartDateTime2) + INCLUDE(SystemId1, IsLongerThanADay2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_StartDateTime2_EndDateTime2_INCLUDE_SystemId1_WHERE_IsLongerThanADay2_1 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, StartDateTime2, EndDateTime2) + INCLUDE(SystemId1) WHERE IsLongerThanADay2 = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_EndDateTime2_StartDateTime2_INCLUDE_SystemId1_WHERE_IsLongerThanADay2_1 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, EndDateTime2, StartDateTime2) + INCLUDE(SystemId1) WHERE IsLongerThanADay2 = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenNumberNumberCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + SingleValue3 DECIMAL (36, 18) NULL, + LowValue3 DECIMAL (36, 18) NULL, + HighValue3 DECIMAL (36, 18) NULL, + HasRange BIT NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenNumberNumberCompositeSearchParam + ADD CONSTRAINT CHK_TokenNumberNumberCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenNumberNumberCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenNumberNumberCompositeSearchParam + ON dbo.TokenNumberNumberCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_SingleValue2_SingleValue3_INCLUDE_SystemId1_WHERE_HasRange_0 + ON dbo.TokenNumberNumberCompositeSearchParam(SearchParamId, Code1, SingleValue2, SingleValue3) + INCLUDE(SystemId1) WHERE HasRange = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_LowValue2_HighValue2_LowValue3_HighValue3_INCLUDE_SystemId1_WHERE_HasRange_1 + ON dbo.TokenNumberNumberCompositeSearchParam(SearchParamId, Code1, LowValue2, HighValue2, LowValue3, HighValue3) + INCLUDE(SystemId1) WHERE HasRange = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenQuantityCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SystemId2 INT NULL, + QuantityCodeId2 INT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenQuantityCompositeSearchParam + ADD CONSTRAINT CHK_TokenQuantityCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenQuantityCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenQuantityCompositeSearchParam + ON dbo.TokenQuantityCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_SingleValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_SingleValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, SingleValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE SingleValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_LowValue2_HighValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_LowValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, LowValue2, HighValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE LowValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_HighValue2_LowValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_LowValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, HighValue2, LowValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE LowValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + Code VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenSearchParam + ADD CONSTRAINT CHK_TokenSearchParam_CodeOverflow CHECK (LEN(Code) = 256 + OR CodeOverflow IS NULL); + +ALTER TABLE dbo.TokenSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenSearchParam + ON dbo.TokenSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code_INCLUDE_SystemId + ON dbo.TokenSearchParam(SearchParamId, Code) + INCLUDE(SystemId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenStringCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + Text2 NVARCHAR (256) COLLATE Latin1_General_CI_AI NOT NULL, + TextOverflow2 NVARCHAR (MAX) COLLATE Latin1_General_CI_AI NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenStringCompositeSearchParam + ADD CONSTRAINT CHK_TokenStringCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenStringCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenStringCompositeSearchParam + ON dbo.TokenStringCompositeSearchParam(ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Text2_INCLUDE_SystemId1_TextOverflow2 + ON dbo.TokenStringCompositeSearchParam(SearchParamId, Code1, Text2) + INCLUDE(SystemId1, TextOverflow2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Text2_INCLUDE_SystemId1_WHERE_TextOverflow2_NOT_NULL + ON dbo.TokenStringCompositeSearchParam(SearchParamId, Code1, Text2) + INCLUDE(SystemId1) WHERE TextOverflow2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenText ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (400) COLLATE Latin1_General_CI_AI NOT NULL, + IsHistory BIT NOT NULL +); + +ALTER TABLE dbo.TokenText + ADD CONSTRAINT DF_TokenText_IsHistory DEFAULT 0 FOR IsHistory; + +ALTER TABLE dbo.TokenText SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenText + ON dbo.TokenText(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE NONCLUSTERED INDEX IX_TokenText_SearchParamId_Text + ON dbo.TokenText(ResourceTypeId, SearchParamId, Text, ResourceSurrogateId) WHERE IsHistory = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenTokenCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam + ADD CONSTRAINT CHK_TokenTokenCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam + ADD CONSTRAINT CHK_TokenTokenCompositeSearchParam_CodeOverflow2 CHECK (LEN(Code2) = 256 + OR CodeOverflow2 IS NULL); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenTokenCompositeSearchParam + ON dbo.TokenTokenCompositeSearchParam(ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Code2_INCLUDE_SystemId1_SystemId2 + ON dbo.TokenTokenCompositeSearchParam(SearchParamId, Code1, Code2) + INCLUDE(SystemId1, SystemId2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.Transactions ( + SurrogateIdRangeFirstValue BIGINT NOT NULL, + SurrogateIdRangeLastValue BIGINT NOT NULL, + Definition VARCHAR (2000) NULL, + IsCompleted BIT CONSTRAINT DF_Transactions_IsCompleted DEFAULT 0 NOT NULL, + IsSuccess BIT CONSTRAINT DF_Transactions_IsSuccess DEFAULT 0 NOT NULL, + IsVisible BIT CONSTRAINT DF_Transactions_IsVisible DEFAULT 0 NOT NULL, + IsHistoryMoved BIT CONSTRAINT DF_Transactions_IsHistoryMoved DEFAULT 0 NOT NULL, + CreateDate DATETIME CONSTRAINT DF_Transactions_CreateDate DEFAULT getUTCdate() NOT NULL, + EndDate DATETIME NULL, + VisibleDate DATETIME NULL, + HistoryMovedDate DATETIME NULL, + HeartbeatDate DATETIME CONSTRAINT DF_Transactions_HeartbeatDate DEFAULT getUTCdate() NOT NULL, + FailureReason VARCHAR (MAX) NULL, + IsControlledByClient BIT CONSTRAINT DF_Transactions_IsControlledByClient DEFAULT 1 NOT NULL, + InvisibleHistoryRemovedDate DATETIME NULL CONSTRAINT PKC_Transactions_SurrogateIdRangeFirstValue PRIMARY KEY CLUSTERED (SurrogateIdRangeFirstValue) +); + +CREATE INDEX IX_IsVisible + ON dbo.Transactions(IsVisible); + +CREATE TABLE dbo.UriSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL +); + +ALTER TABLE dbo.UriSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_UriSearchParam + ON dbo.UriSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Uri + ON dbo.UriSearchParam(SearchParamId, Uri) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.WatchdogLeases ( + Watchdog VARCHAR (100) NOT NULL, + LeaseHolder VARCHAR (100) CONSTRAINT DF_WatchdogLeases_LeaseHolder DEFAULT '' NOT NULL, + LeaseEndTime DATETIME CONSTRAINT DF_WatchdogLeases_LeaseEndTime DEFAULT 0 NOT NULL, + RemainingLeaseTimeSec AS datediff(second, getUTCdate(), LeaseEndTime), + LeaseRequestor VARCHAR (100) CONSTRAINT DF_WatchdogLeases_LeaseRequestor DEFAULT '' NOT NULL, + LeaseRequestTime DATETIME CONSTRAINT DF_WatchdogLeases_LeaseRequestTime DEFAULT 0 NOT NULL CONSTRAINT PKC_WatchdogLeases_Watchdog PRIMARY KEY CLUSTERED (Watchdog) +); + +COMMIT +GO +CREATE PROCEDURE dbo.AcquireReindexJobs +@jobHeartbeatTimeoutThresholdInSeconds BIGINT, @maximumNumberOfConcurrentJobsAllowed INT +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; +BEGIN TRANSACTION; +DECLARE @expirationDateTime AS DATETIME2 (7); +SELECT @expirationDateTime = DATEADD(second, -@jobHeartbeatTimeoutThresholdInSeconds, SYSUTCDATETIME()); +DECLARE @numberOfRunningJobs AS INT; +SELECT @numberOfRunningJobs = COUNT(*) +FROM dbo.ReindexJob WITH (TABLOCKX) +WHERE Status = 'Running' + AND HeartbeatDateTime > @expirationDateTime; +DECLARE @limit AS INT = @maximumNumberOfConcurrentJobsAllowed - @numberOfRunningJobs; +IF (@limit > 0) + BEGIN + DECLARE @availableJobs TABLE ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + JobVersion BINARY (8) NOT NULL); + INSERT INTO @availableJobs + SELECT TOP (@limit) Id, + JobVersion + FROM dbo.ReindexJob + WHERE (Status = 'Queued' + OR (Status = 'Running' + AND HeartbeatDateTime <= @expirationDateTime)) + ORDER BY HeartbeatDateTime; + DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); + UPDATE dbo.ReindexJob + SET Status = 'Running', + HeartbeatDateTime = @heartbeatDateTime, + RawJobRecord = JSON_MODIFY(RawJobRecord, '$.status', 'Running') + OUTPUT inserted.RawJobRecord, inserted.JobVersion + FROM dbo.ReindexJob AS job + INNER JOIN + @availableJobs AS availableJob + ON job.Id = availableJob.Id + AND job.JobVersion = availableJob.JobVersion; + END +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.AcquireWatchdogLease +@Watchdog VARCHAR (100), @Worker VARCHAR (100), @AllowRebalance BIT=1, @ForceAcquire BIT=0, @LeasePeriodSec FLOAT, @WorkerIsRunning BIT=0, @LeaseEndTime DATETIME OUTPUT, @IsAcquired BIT OUTPUT, @CurrentLeaseHolder VARCHAR (100)=NULL OUTPUT +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +DECLARE @SP AS VARCHAR (100) = 'AcquireWatchdogLease', @Mode AS VARCHAR (100), @msg AS VARCHAR (1000), @MyLeasesNumber AS INT, @OtherValidRequestsOrLeasesNumber AS INT, @MyValidRequestsOrLeasesNumber AS INT, @DesiredLeasesNumber AS INT, @NotLeasedWatchdogNumber AS INT, @WatchdogNumber AS INT, @Now AS DATETIME, @MyLastChangeTime AS DATETIME, @PreviousLeaseHolder AS VARCHAR (100), @Rows AS INT = 0, @NumberOfWorkers AS INT, @st AS DATETIME = getUTCdate(), @RowsInt AS INT, @Pattern AS VARCHAR (100); +BEGIN TRY + SET @Mode = 'R=' + isnull(@Watchdog, 'NULL') + ' W=' + isnull(@Worker, 'NULL') + ' F=' + isnull(CONVERT (VARCHAR, @ForceAcquire), 'NULL') + ' LP=' + isnull(CONVERT (VARCHAR, @LeasePeriodSec), 'NULL'); + SET @CurrentLeaseHolder = ''; + SET @IsAcquired = 0; + SET @Now = getUTCdate(); + SET @LeaseEndTime = @Now; + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderIncludePatternFor' + @Watchdog), ''); + IF @Pattern IS NULL + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderIncludePattern'), ''); + IF @Pattern IS NOT NULL + AND @Worker NOT LIKE @Pattern + BEGIN + SET @msg = 'Worker does not match include pattern=' + @Pattern; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; + SET @CurrentLeaseHolder = isnull((SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog), ''); + RETURN; + END + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderExcludePatternFor' + @Watchdog), ''); + IF @Pattern IS NULL + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderExcludePattern'), ''); + IF @Pattern IS NOT NULL + AND @Worker LIKE @Pattern + BEGIN + SET @msg = 'Worker matches exclude pattern=' + @Pattern; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; + SET @CurrentLeaseHolder = isnull((SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog), ''); + RETURN; + END + DECLARE @Watchdogs TABLE ( + Watchdog VARCHAR (100) PRIMARY KEY); + INSERT INTO @Watchdogs + SELECT Watchdog + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE RemainingLeaseTimeSec * (-1) > 10 * @LeasePeriodSec + OR @ForceAcquire = 1 + AND Watchdog = @Watchdog + AND LeaseHolder <> @Worker; + IF @@rowcount > 0 + BEGIN + DELETE dbo.WatchdogLeases + WHERE Watchdog IN (SELECT Watchdog + FROM @Watchdogs); + SET @Rows += @@rowcount; + IF @Rows > 0 + BEGIN + SET @msg = ''; + SELECT @msg = CONVERT (VARCHAR (1000), @msg + CASE WHEN @msg = '' THEN '' ELSE ',' END + Watchdog) + FROM @Watchdogs; + SET @msg = CONVERT (VARCHAR (1000), 'Remove old/forced leases:' + @msg); + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Target = 'WatchdogLeases', @Action = 'Delete', @Rows = @Rows, @Text = @msg; + END + END + SET @NumberOfWorkers = 1 + (SELECT count(*) + FROM (SELECT LeaseHolder + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder <> @Worker + UNION + SELECT LeaseRequestor + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseRequestor <> @Worker + AND LeaseRequestor <> '') AS A); + SET @Mode = CONVERT (VARCHAR (100), @Mode + ' N=' + CONVERT (VARCHAR (10), @NumberOfWorkers)); + IF NOT EXISTS (SELECT * + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE Watchdog = @Watchdog) + INSERT INTO dbo.WatchdogLeases (Watchdog, LeaseEndTime, LeaseRequestTime) + SELECT @Watchdog, + dateadd(day, -10, @Now), + dateadd(day, -10, @Now) + WHERE NOT EXISTS (SELECT * + FROM dbo.WatchdogLeases WITH (TABLOCKX) + WHERE Watchdog = @Watchdog); + SET @LeaseEndTime = dateadd(second, @LeasePeriodSec, @Now); + SET @WatchdogNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK)); + SET @NotLeasedWatchdogNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = '' + OR LeaseEndTime < @Now); + SET @MyLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = @Worker + AND LeaseEndTime > @Now); + SET @OtherValidRequestsOrLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder <> @Worker + AND LeaseEndTime > @Now + OR LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec); + SET @MyValidRequestsOrLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = @Worker + AND LeaseEndTime > @Now + OR LeaseRequestor = @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec); + SET @DesiredLeasesNumber = ceiling(1.0 * @WatchdogNumber / @NumberOfWorkers); + IF @DesiredLeasesNumber = 0 + SET @DesiredLeasesNumber = 1; + IF @DesiredLeasesNumber = 1 + AND @OtherValidRequestsOrLeasesNumber = 1 + AND @WatchdogNumber = 1 + SET @DesiredLeasesNumber = 0; + IF @MyValidRequestsOrLeasesNumber = floor(1.0 * @WatchdogNumber / @NumberOfWorkers) + AND @OtherValidRequestsOrLeasesNumber + @MyValidRequestsOrLeasesNumber = @WatchdogNumber + SET @DesiredLeasesNumber = @DesiredLeasesNumber - 1; + UPDATE dbo.WatchdogLeases + SET LeaseHolder = @Worker, + LeaseEndTime = @LeaseEndTime, + LeaseRequestor = '', + @PreviousLeaseHolder = LeaseHolder + WHERE Watchdog = @Watchdog + AND NOT (LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec) + AND (LeaseHolder = @Worker + AND (LeaseEndTime > @Now + OR @WorkerIsRunning = 1) + OR LeaseEndTime < @Now + AND (@DesiredLeasesNumber > @MyLeasesNumber + OR @OtherValidRequestsOrLeasesNumber < @WatchdogNumber)); + IF @@rowcount > 0 + BEGIN + SET @IsAcquired = 1; + SET @msg = 'Lease holder changed from [' + isnull(@PreviousLeaseHolder, '') + '] to [' + @Worker + ']'; + IF @PreviousLeaseHolder <> @Worker + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Text = @msg; + END + ELSE + IF @AllowRebalance = 1 + BEGIN + SET @CurrentLeaseHolder = (SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog); + UPDATE dbo.WatchdogLeases + SET LeaseRequestTime = @Now + WHERE Watchdog = @Watchdog + AND LeaseRequestor = @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec; + IF @DesiredLeasesNumber > @MyValidRequestsOrLeasesNumber + BEGIN + UPDATE A + SET LeaseRequestor = @Worker, + LeaseRequestTime = @Now + FROM dbo.WatchdogLeases AS A + WHERE Watchdog = @Watchdog + AND NOT (LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec) + AND @NotLeasedWatchdogNumber = 0 + AND (SELECT count(*) + FROM dbo.WatchdogLeases AS B + WHERE B.LeaseHolder = A.LeaseHolder + AND datediff(second, B.LeaseEndTime, @Now) < @LeasePeriodSec) > @DesiredLeasesNumber; + SET @RowsInt = @@rowcount; + SET @msg = '@DesiredLeasesNumber=[' + CONVERT (VARCHAR (10), @DesiredLeasesNumber) + '] > @MyValidRequestsOrLeasesNumber=[' + CONVERT (VARCHAR (10), @MyValidRequestsOrLeasesNumber) + ']'; + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Rows = @RowsInt, @Text = @msg; + END + END + SET @Mode = CONVERT (VARCHAR (100), @Mode + ' A=' + CONVERT (VARCHAR (1), @IsAcquired)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Error', @Mode = @Mode; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.AddPartitionOnResourceChanges +@partitionBoundary DATETIME2 (7) OUTPUT +AS +BEGIN + SET XACT_ABORT ON; + BEGIN TRANSACTION; + DECLARE @rightPartitionBoundary AS DATETIME2 (7) = CAST ((SELECT TOP (1) value + FROM sys.partition_range_values AS prv + INNER JOIN + sys.partition_functions AS pf + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + ORDER BY prv.boundary_id DESC) AS DATETIME2 (7)); + DECLARE @timestamp AS DATETIME2 (7) = DATEADD(hour, DATEDIFF(hour, 0, sysutcdatetime()), 0); + IF (@rightPartitionBoundary < @timestamp) + BEGIN + SET @rightPartitionBoundary = @timestamp; + END + SET @rightPartitionBoundary = DATEADD(hour, 1, @rightPartitionBoundary); + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [Primary]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@rightPartitionBoundary); + SET @partitionBoundary = @rightPartitionBoundary; + COMMIT TRANSACTION; +END + +GO +CREATE PROCEDURE dbo.ArchiveJobs +@QueueType TINYINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'ArchiveJobs', @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0, @InflightRows AS INT = 0, @Lock AS VARCHAR (100) = 'DequeueJob_' + CONVERT (VARCHAR, @QueueType); +BEGIN TRY + SET @PartitionId = @MaxPartitions * rand(); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + WHILE @LookedAtPartitions <= @MaxPartitions + BEGIN + SET @InflightRows += (SELECT count(*) + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (0, 1)); + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + IF @InflightRows = 0 + BEGIN + SET @LookedAtPartitions = 0; + WHILE @LookedAtPartitions <= @MaxPartitions + BEGIN + UPDATE dbo.JobQueue + SET Status = 5 + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (2, 3, 4); + SET @Rows += @@rowcount; + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.AssignResourceIdInts +@Count INT, @FirstIdInt BIGINT OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'AssignResourceIdInts', @Mode AS VARCHAR (200) = 'Cnt=' + CONVERT (VARCHAR, @Count), @st AS DATETIME = getUTCdate(), @FirstValueVar AS SQL_VARIANT, @LastValueVar AS SQL_VARIANT, @SequenceRangeFirstValue AS INT; +BEGIN TRY + SET @FirstValueVar = NULL; + WHILE @FirstValueVar IS NULL + BEGIN + EXECUTE sys.sp_sequence_get_range @sequence_name = 'dbo.ResourceIdIntMapSequence', @range_size = @Count, @range_first_value = @FirstValueVar OUTPUT, @range_last_value = @LastValueVar OUTPUT; + SET @SequenceRangeFirstValue = CONVERT (INT, @FirstValueVar); + IF @SequenceRangeFirstValue > CONVERT (INT, @LastValueVar) + SET @FirstValueVar = NULL; + END + SET @FirstIdInt = datediff_big(millisecond, '0001-01-01', sysUTCdatetime()) * 80000 + @SequenceRangeFirstValue; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.CaptureResourceChanges +@isDeleted BIT, @version INT, @resourceId VARCHAR (64), @resourceTypeId SMALLINT +AS +BEGIN + DECLARE @changeType AS SMALLINT; + IF (@isDeleted = 1) + BEGIN + SET @changeType = 2; + END + ELSE + BEGIN + IF (@version = 1) + BEGIN + SET @changeType = 0; + END + ELSE + BEGIN + SET @changeType = 1; + END + END + INSERT INTO dbo.ResourceChangeData (ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId) + VALUES (@resourceId, @resourceTypeId, @version, @changeType); +END + +GO +CREATE PROCEDURE dbo.CaptureResourceIdsForChanges +@Resources dbo.ResourceList READONLY +AS +SET NOCOUNT ON; +INSERT INTO dbo.ResourceChangeData (ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId) +SELECT ResourceId, + ResourceTypeId, + Version, + CASE WHEN IsDeleted = 1 THEN 2 WHEN Version > 1 THEN 1 ELSE 0 END +FROM @Resources +WHERE IsHistory = 0; + +GO +CREATE PROCEDURE dbo.CheckActiveReindexJobs +AS +SET NOCOUNT ON; +SELECT Id +FROM dbo.ReindexJob +WHERE Status = 'Running' + OR Status = 'Queued' + OR Status = 'Paused'; + +GO +CREATE PROCEDURE dbo.CleanupEventLog +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'CleanupEventLog', @Mode AS VARCHAR (100) = '', @MaxDeleteRows AS INT, @MaxAllowedRows AS BIGINT, @RetentionPeriodSecond AS INT, @DeletedRows AS INT, @TotalDeletedRows AS INT = 0, @TotalRows AS INT, @Now AS DATETIME = getUTCdate(); +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; +BEGIN TRY + SET @MaxDeleteRows = (SELECT Number + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.DeleteBatchSize'); + IF @MaxDeleteRows IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.DeleteBatchSize', 18, 127); + SET @MaxAllowedRows = (SELECT Number + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.AllowedRows'); + IF @MaxAllowedRows IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.AllowedRows', 18, 127); + SET @RetentionPeriodSecond = (SELECT Number * 24 * 60 * 60 + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.RetentionPeriodDay'); + IF @RetentionPeriodSecond IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.RetentionPeriodDay', 18, 127); + SET @TotalRows = (SELECT sum(row_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id('EventLog') + AND index_id IN (0, 1)); + SET @DeletedRows = 1; + WHILE @DeletedRows > 0 + AND EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.IsEnabled' + AND Number = 1) + BEGIN + SET @DeletedRows = 0; + IF @TotalRows - @TotalDeletedRows > @MaxAllowedRows + BEGIN + DELETE TOP (@MaxDeleteRows) + dbo.EventLog WITH (PAGLOCK) + WHERE EventDate <= dateadd(second, -@RetentionPeriodSecond, @Now); + SET @DeletedRows = @@rowcount; + SET @TotalDeletedRows += @DeletedRows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'EventLog', @Action = 'Delete', @Rows = @DeletedRows, @Text = @TotalDeletedRows; + END + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @Now; +END TRY +BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.ConfigurePartitionOnResourceChanges +@numberOfFuturePartitionsToAdd INT +AS +BEGIN + SET XACT_ABORT ON; + BEGIN TRANSACTION; + DECLARE @partitionBoundary AS DATETIME2 (7) = DATEADD(hour, DATEDIFF(hour, 0, sysutcdatetime()), 0); + DECLARE @startingRightPartitionBoundary AS DATETIME2 (7) = CAST ((SELECT TOP (1) value + FROM sys.partition_range_values AS prv + INNER JOIN + sys.partition_functions AS pf + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + ORDER BY prv.boundary_id DESC) AS DATETIME2 (7)); + DECLARE @numberOfPartitionsToAdd AS INT = @numberOfFuturePartitionsToAdd + 1; + WHILE @numberOfPartitionsToAdd > 0 + BEGIN + IF (@startingRightPartitionBoundary < @partitionBoundary) + BEGIN + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [PRIMARY]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@partitionBoundary); + END + SET @partitionBoundary = DATEADD(hour, 1, @partitionBoundary); + SET @numberOfPartitionsToAdd -= 1; + END + COMMIT TRANSACTION; +END + +GO +CREATE PROCEDURE dbo.CreateReindexJob +@id VARCHAR (64), @status VARCHAR (10), @rawJobRecord VARCHAR (MAX) +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +BEGIN TRANSACTION; +DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); +INSERT INTO dbo.ReindexJob (Id, Status, HeartbeatDateTime, RawJobRecord) +VALUES (@id, @status, @heartbeatDateTime, @rawJobRecord); +SELECT CAST (MIN_ACTIVE_ROWVERSION() AS INT); +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.CreateResourceSearchParamStats +@Table VARCHAR (100), @Column VARCHAR (100), @ResourceTypeId SMALLINT, @SearchParamId SMALLINT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'T=' + isnull(@Table, 'NULL') + ' C=' + isnull(@Column, 'NULL') + ' RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' SP=' + isnull(CONVERT (VARCHAR, @SearchParamId), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + IF @Table IS NULL + OR @Column IS NULL + OR @ResourceTypeId IS NULL + OR @SearchParamId IS NULL + RAISERROR ('@TableName IS NULL OR @KeyColumn IS NULL OR @ResourceTypeId IS NULL OR @SearchParamId IS NULL', 18, 127); + EXECUTE ('CREATE STATISTICS ST_' + @Column + '_WHERE_ResourceTypeId_' + @ResourceTypeId + '_SearchParamId_' + @SearchParamId + ' ON dbo.' + @Table + ' (' + @Column + ') WHERE ResourceTypeId = ' + @ResourceTypeId + ' AND SearchParamId = ' + @SearchParamId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = 'Stats created'; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF error_number() = 1927 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; + RETURN; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.Defrag +@TableName VARCHAR (100), @IndexName VARCHAR (200), @PartitionNumber INT, @IsPartitioned BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'Defrag', @Mode AS VARCHAR (200) = @TableName + '.' + @IndexName + '.' + CONVERT (VARCHAR, @PartitionNumber) + '.' + CONVERT (VARCHAR, @IsPartitioned), @st AS DATETIME = getUTCdate(), @SQL AS VARCHAR (3500), @msg AS VARCHAR (1000), @SizeBefore AS FLOAT, @SizeAfter AS FLOAT, @IndexId AS INT; +BEGIN TRY + SET @IndexId = (SELECT index_id + FROM sys.indexes + WHERE object_id = object_id(@TableName) + AND name = @IndexName); + SET @SizeBefore = (SELECT sum(reserved_page_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId) * 8.0 / 1024 / 1024; + SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start', @Text = @msg; + SET @Sql = 'ALTER INDEX ' + quotename(@IndexName) + ' ON dbo.' + quotename(@TableName) + ' REORGANIZE' + CASE WHEN @IsPartitioned = 1 THEN ' PARTITION = ' + CONVERT (VARCHAR, @PartitionNumber) ELSE '' END; + BEGIN TRY + EXECUTE (@Sql); + SET @SizeAfter = (SELECT sum(reserved_page_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId) * 8.0 / 1024 / 1024; + SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore) + ', after=' + CONVERT (VARCHAR, @SizeAfter) + ', reduced by=' + CONVERT (VARCHAR, @SizeBefore - @SizeAfter); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'End', @Mode = @Mode, @Action = 'Reorganize', @Start = @st, @Text = @msg; + END TRY + BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Error', @Mode = @Mode, @Action = 'Reorganize', @Start = @st, @ReRaisError = 0; + END CATCH +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DefragChangeDatabaseSettings +@IsOn BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DefragChangeDatabaseSettings', @Mode AS VARCHAR (200) = 'On=' + CONVERT (VARCHAR, @IsOn), @st AS DATETIME = getUTCdate(), @SQL AS VARCHAR (3500); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Start', @Mode = @Mode; + SET @SQL = 'ALTER DATABASE CURRENT SET AUTO_UPDATE_STATISTICS ' + CASE WHEN @IsOn = 1 THEN 'ON' ELSE 'OFF' END; + EXECUTE (@SQL); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Run', @Mode = @Mode, @Text = @SQL; + SET @SQL = 'ALTER DATABASE CURRENT SET AUTO_CREATE_STATISTICS ' + CASE WHEN @IsOn = 1 THEN 'ON' ELSE 'OFF' END; + EXECUTE (@SQL); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'End', @Mode = @Mode, @Start = @st, @Text = @SQL; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DeleteHistory +@DeleteResources BIT=0, @Reset BIT=0, @DisableLogEvent BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DeleteHistory', @Mode AS VARCHAR (100) = 'D=' + isnull(CONVERT (VARCHAR, @DeleteResources), 'NULL') + ' R=' + isnull(CONVERT (VARCHAR, @Reset), 'NULL'), @st AS DATETIME = getUTCdate(), @Id AS VARCHAR (100) = 'DeleteHistory.LastProcessed.TypeId.SurrogateId', @ResourceTypeId AS SMALLINT, @SurrogateId AS BIGINT, @RowsToProcess AS INT, @ProcessedResources AS INT = 0, @DeletedResources AS INT = 0, @DeletedSearchParams AS INT = 0, @ReportDate AS DATETIME = getUTCdate(); +BEGIN TRY + IF @DisableLogEvent = 0 + INSERT INTO dbo.Parameters (Id, Char) + SELECT @SP, + 'LogEvent'; + ELSE + DELETE dbo.Parameters + WHERE Id = @SP; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + INSERT INTO dbo.Parameters (Id, Char) + SELECT @Id, + '0.0' + WHERE NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = @Id); + DECLARE @LastProcessed AS VARCHAR (100) = CASE WHEN @Reset = 0 THEN (SELECT Char + FROM dbo.Parameters + WHERE Id = @Id) ELSE '0.0' END; + DECLARE @Types TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + DECLARE @SurrogateIds TABLE ( + ResourceSurrogateId BIGINT PRIMARY KEY, + IsHistory BIT ); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Insert', @Rows = @@rowcount; + SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1); + SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255); + DELETE @Types + WHERE ResourceTypeId < @ResourceTypeId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Delete', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @Types + ORDER BY ResourceTypeId); + SET @ProcessedResources = 0; + SET @DeletedResources = 0; + SET @DeletedSearchParams = 0; + SET @RowsToProcess = 1; + WHILE @RowsToProcess > 0 + BEGIN + DELETE @SurrogateIds; + INSERT INTO @SurrogateIds + SELECT TOP 10000 ResourceSurrogateId, + IsHistory + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId + ORDER BY ResourceSurrogateId; + SET @RowsToProcess = @@rowcount; + SET @ProcessedResources += @RowsToProcess; + IF @RowsToProcess > 0 + SET @SurrogateId = (SELECT max(ResourceSurrogateId) + FROM @SurrogateIds); + SET @LastProcessed = CONVERT (VARCHAR, @ResourceTypeId) + '.' + CONVERT (VARCHAR, @SurrogateId); + DELETE @SurrogateIds + WHERE IsHistory = 0; + IF EXISTS (SELECT * + FROM @SurrogateIds) + BEGIN + DELETE dbo.ResourceWriteClaim + WHERE ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.CompartmentAssignment + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.ReferenceSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenText + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.StringSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.UriSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.NumberSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.QuantitySearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.DateTimeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.ReferenceTokenCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenTokenCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenDateTimeCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenQuantityCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenStringCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenNumberNumberCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + IF @DeleteResources = 1 + BEGIN + DELETE dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedResources += @@rowcount; + END + END + UPDATE dbo.Parameters + SET Char = @LastProcessed + WHERE Id = @Id; + IF datediff(second, @ReportDate, getUTCdate()) > 60 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Select', @Rows = @ProcessedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '*SearchParam', @Action = 'Delete', @Rows = @DeletedSearchParams, @Text = @LastProcessed; + IF @DeleteResources = 1 + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Rows = @DeletedResources, @Text = @LastProcessed; + SET @ReportDate = getUTCdate(); + SET @ProcessedResources = 0; + SET @DeletedSearchParams = 0; + SET @DeletedResources = 0; + END + END + DELETE @Types + WHERE ResourceTypeId = @ResourceTypeId; + SET @SurrogateId = 0; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Select', @Rows = @ProcessedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '*SearchParam', @Action = 'Delete', @Rows = @DeletedSearchParams, @Text = @LastProcessed; + IF @DeleteResources = 1 + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Rows = @DeletedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DequeueJob +@QueueType TINYINT, @Worker VARCHAR (100), @HeartbeatTimeoutSec INT, @InputJobId BIGINT=NULL, @CheckTimeoutJobs BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DequeueJob', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' H=' + isnull(CONVERT (VARCHAR, @HeartbeatTimeoutSec), 'NULL') + ' W=' + isnull(@Worker, 'NULL') + ' IJ=' + isnull(CONVERT (VARCHAR, @InputJobId), 'NULL') + ' T=' + isnull(CONVERT (VARCHAR, @CheckTimeoutJobs), 'NULL'), @Rows AS INT = 0, @st AS DATETIME = getUTCdate(), @JobId AS BIGINT, @msg AS VARCHAR (100), @Lock AS VARCHAR (100), @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0; +BEGIN TRY + IF EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'DequeueJobStop' + AND Number = 1) + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = 0, @Text = 'Skipped'; + RETURN; + END + IF @InputJobId IS NULL + SET @PartitionId = @MaxPartitions * rand(); + ELSE + SET @PartitionId = @InputJobId % 16; + SET TRANSACTION ISOLATION LEVEL READ COMMITTED; + WHILE @InputJobId IS NULL + AND @JobId IS NULL + AND @LookedAtPartitions < @MaxPartitions + AND @CheckTimeoutJobs = 0 + BEGIN + SET @Lock = 'DequeueJob_' + CONVERT (VARCHAR, @QueueType) + '_' + CONVERT (VARCHAR, @PartitionId); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + UPDATE T + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = T.JobId + FROM dbo.JobQueue AS T WITH (PAGLOCK) + INNER JOIN + (SELECT TOP 1 JobId + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_PartitionId_Status_Priority)) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 0 + ORDER BY Priority, JobId) AS S + ON QueueType = @QueueType + AND PartitionId = @PartitionId + AND T.JobId = S.JobId; + SET @Rows += @@rowcount; + COMMIT TRANSACTION; + IF @JobId IS NULL + BEGIN + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + SET @LookedAtPartitions = 0; + WHILE @InputJobId IS NULL + AND @JobId IS NULL + AND @LookedAtPartitions < @MaxPartitions + BEGIN + SET @Lock = 'DequeueStoreCopyWorkUnit_' + CONVERT (VARCHAR, @PartitionId); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + UPDATE T + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = CASE WHEN CancelRequested = 0 THEN 1 ELSE 4 END, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = CASE WHEN CancelRequested = 0 THEN T.JobId END, + Info = CONVERT (VARCHAR (1000), isnull(Info, '') + ' Prev: Worker=' + Worker + ' Start=' + CONVERT (VARCHAR, StartDate, 121)) + FROM dbo.JobQueue AS T WITH (PAGLOCK) + INNER JOIN + (SELECT TOP 1 JobId + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_PartitionId_Status_Priority)) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 1 + AND datediff(second, HeartbeatDate, getUTCdate()) > @HeartbeatTimeoutSec + ORDER BY Priority, JobId) AS S + ON QueueType = @QueueType + AND PartitionId = @PartitionId + AND T.JobId = S.JobId; + SET @Rows += @@rowcount; + COMMIT TRANSACTION; + IF @JobId IS NULL + BEGIN + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + IF @InputJobId IS NOT NULL + BEGIN + UPDATE dbo.JobQueue WITH (PAGLOCK) + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = JobId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 0 + AND JobId = @InputJobId; + SET @Rows += @@rowcount; + IF @JobId IS NULL + BEGIN + UPDATE dbo.JobQueue WITH (PAGLOCK) + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = JobId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 1 + AND JobId = @InputJobId + AND datediff(second, HeartbeatDate, getUTCdate()) > @HeartbeatTimeoutSec; + SET @Rows += @@rowcount; + END + END + IF @JobId IS NOT NULL + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobId = @JobId; + SET @msg = 'J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL') + ' P=' + CONVERT (VARCHAR, @PartitionId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DisableIndex +@tableName NVARCHAR (128), @indexName NVARCHAR (128) +WITH EXECUTE AS 'dbo' +AS +DECLARE @errorTxt AS VARCHAR (1000), @sql AS NVARCHAR (1000), @isDisabled AS BIT; +IF object_id(@tableName) IS NULL + BEGIN + SET @errorTxt = @tableName + ' does not exist or you don''t have permissions.'; + RAISERROR (@errorTxt, 18, 127); + END +SET @isDisabled = (SELECT is_disabled + FROM sys.indexes + WHERE object_id = object_id(@tableName) + AND name = @indexName); +IF @isDisabled IS NULL + BEGIN + SET @errorTxt = @indexName + ' does not exist or you don''t have permissions.'; + RAISERROR (@errorTxt, 18, 127); + END +IF @isDisabled = 0 + BEGIN + SET @sql = N'ALTER INDEX ' + QUOTENAME(@indexName) + N' on ' + @tableName + ' Disable'; + EXECUTE sp_executesql @sql; + END + +GO +CREATE PROCEDURE dbo.DisableIndexes +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DisableIndexes', @Mode AS VARCHAR (200) = '', @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100), @Ind AS VARCHAR (200), @Txt AS VARCHAR (4000); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + Tbl VARCHAR (100) PRIMARY KEY, + Supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + DECLARE @Indexes TABLE ( + Tbl VARCHAR (100), + Ind VARCHAR (200), + TblId INT , + IndId INT PRIMARY KEY (Tbl, Ind)); + INSERT INTO @Indexes + SELECT Tbl, + I.Name, + TblId, + I.index_id + FROM (SELECT object_id(Tbl) AS TblId, + Tbl + FROM @Tables) AS O + INNER JOIN + sys.indexes AS I + ON I.object_id = TblId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + INSERT INTO dbo.IndexProperties (TableName, IndexName, PropertyName, PropertyValue) + SELECT Tbl, + Ind, + 'DATA_COMPRESSION', + data_comp + FROM (SELECT Tbl, + Ind, + isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions + WHERE object_id = TblId + AND index_id = IndId), 'NONE') AS data_comp + FROM @Indexes) AS A + WHERE NOT EXISTS (SELECT * + FROM dbo.IndexProperties + WHERE TableName = Tbl + AND IndexName = Ind); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'IndexProperties', @Action = 'Insert', @Rows = @@rowcount; + DELETE @Indexes + WHERE Tbl = 'Resource' + OR IndId = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Delete', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @Tbl = Tbl, + @Ind = Ind + FROM @Indexes; + SET @Txt = 'ALTER INDEX ' + @Ind + ' ON dbo.' + @Tbl + ' DISABLE'; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Ind, @Action = 'Disable', @Text = @Txt; + DELETE @Indexes + WHERE Tbl = @Tbl + AND Ind = @Ind; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.EnqueueJobs +@QueueType TINYINT, @Definitions StringList READONLY, @GroupId BIGINT=NULL, @ForceOneActiveJobGroup BIT=1, @IsCompleted BIT=NULL, @ReturnJobs BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'EnqueueJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' D=' + CONVERT (VARCHAR, (SELECT count(*) + FROM @Definitions)) + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL') + ' F=' + isnull(CONVERT (VARCHAR, @ForceOneActiveJobGroup), 'NULL') + ' C=' + isnull(CONVERT (VARCHAR, @IsCompleted), 'NULL'), @st AS DATETIME = getUTCdate(), @Lock AS VARCHAR (100) = 'EnqueueJobs_' + CONVERT (VARCHAR, @QueueType), @MaxJobId AS BIGINT, @Rows AS INT, @msg AS VARCHAR (1000), @JobIds AS BigintList, @InputRows AS INT; +BEGIN TRY + DECLARE @Input TABLE ( + DefinitionHash VARBINARY (20) PRIMARY KEY, + Definition VARCHAR (MAX) ); + INSERT INTO @Input + SELECT hashbytes('SHA1', String) AS DefinitionHash, + String AS Definition + FROM @Definitions; + SET @InputRows = @@rowcount; + INSERT INTO @JobIds + SELECT JobId + FROM @Input AS A + INNER JOIN + dbo.JobQueue AS B + ON B.QueueType = @QueueType + AND B.DefinitionHash = A.DefinitionHash + AND B.Status <> 5; + IF @@rowcount < @InputRows + BEGIN + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + IF @ForceOneActiveJobGroup = 1 + AND EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND Status IN (0, 1) + AND (@GroupId IS NULL + OR GroupId <> @GroupId)) + RAISERROR ('There are other active job groups', 18, 127); + SET @MaxJobId = isnull((SELECT TOP 1 JobId + FROM dbo.JobQueue + WHERE QueueType = @QueueType + ORDER BY JobId DESC), 0); + INSERT INTO dbo.JobQueue (QueueType, GroupId, JobId, Definition, DefinitionHash, Status) + OUTPUT inserted.JobId INTO @JobIds + SELECT @QueueType, + isnull(@GroupId, @MaxJobId + 1) AS GroupId, + JobId, + Definition, + DefinitionHash, + CASE WHEN @IsCompleted = 1 THEN 2 ELSE 0 END AS Status + FROM (SELECT @MaxJobId + row_number() OVER (ORDER BY Dummy) AS JobId, + * + FROM (SELECT *, + 0 AS Dummy + FROM @Input) AS A) AS A + WHERE NOT EXISTS (SELECT * + FROM dbo.JobQueue AS B WITH (INDEX (IX_QueueType_DefinitionHash)) + WHERE B.QueueType = @QueueType + AND B.DefinitionHash = A.DefinitionHash + AND B.Status <> 5); + SET @Rows = @@rowcount; + COMMIT TRANSACTION; + END + IF @ReturnJobs = 1 + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.ExecuteCommandForRebuildIndexes +@Tbl VARCHAR (100), @Ind VARCHAR (1000), @Cmd VARCHAR (MAX) +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'ExecuteCommandForRebuildIndexes', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL'), @st AS DATETIME, @Retries AS INT = 0, @Action AS VARCHAR (100), @msg AS VARCHAR (1000); +RetryOnTempdbError: +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start', @Text = @Cmd; + SET @st = getUTCdate(); + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + IF @Cmd IS NULL + RAISERROR ('@Cmd IS NULL', 18, 127); + SET @Action = CASE WHEN @Cmd LIKE 'UPDATE STAT%' THEN 'Update statistics' WHEN @Cmd LIKE 'CREATE%INDEX%' THEN 'Create Index' WHEN @Cmd LIKE 'ALTER%INDEX%REBUILD%' THEN 'Rebuild Index' WHEN @Cmd LIKE 'ALTER%TABLE%ADD%' THEN 'Add Constraint' END; + IF @Action IS NULL + BEGIN + SET @msg = 'Not supported command = ' + CONVERT (VARCHAR (900), @Cmd); + RAISERROR (@msg, 18, 127); + END + IF @Action = 'Create Index' + WAITFOR DELAY '00:00:05'; + EXECUTE (@Cmd); + SELECT @Ind; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Action = @Action, @Status = 'End', @Start = @st, @Text = @Cmd; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF error_number() = 40544 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st, @Retry = @Retries; + SET @Retries = @Retries + 1; + IF @Tbl = 'TokenText_96' + WAITFOR DELAY '01:00:00'; + ELSE + WAITFOR DELAY '00:10:00'; + GOTO RetryOnTempdbError; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.FetchEventAgentCheckpoint +@CheckpointId VARCHAR (64) +AS +BEGIN + SELECT TOP (1) CheckpointId, + LastProcessedDateTime, + LastProcessedIdentifier + FROM dbo.EventAgentCheckpoint + WHERE CheckpointId = @CheckpointId; +END + +GO +CREATE PROCEDURE dbo.FetchResourceChanges_3 +@startId BIGINT, @lastProcessedUtcDateTime DATETIME2 (7), @pageSize SMALLINT +AS +BEGIN + SET NOCOUNT ON; + DECLARE @precedingPartitionBoundary AS DATETIME2 (7) = (SELECT TOP (1) CAST (prv.value AS DATETIME2 (7)) AS value + FROM sys.partition_range_values AS prv WITH (NOLOCK) + INNER JOIN + sys.partition_functions AS pf WITH (NOLOCK) + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + AND SQL_VARIANT_PROPERTY(prv.Value, 'BaseType') = 'datetime2' + AND CAST (prv.value AS DATETIME2 (7)) < DATEADD(HOUR, DATEDIFF(HOUR, 0, @lastProcessedUtcDateTime), 0) + ORDER BY prv.boundary_id DESC); + IF (@precedingPartitionBoundary IS NULL) + BEGIN + SET @precedingPartitionBoundary = CONVERT (DATETIME2 (7), N'1970-01-01T00:00:00.0000000'); + END + DECLARE @endDateTimeToFilter AS DATETIME2 (7) = DATEADD(HOUR, 1, SYSUTCDATETIME()); + WITH PartitionBoundaries + AS (SELECT CAST (prv.value AS DATETIME2 (7)) AS PartitionBoundary + FROM sys.partition_range_values AS prv WITH (NOLOCK) + INNER JOIN + sys.partition_functions AS pf WITH (NOLOCK) + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + AND SQL_VARIANT_PROPERTY(prv.Value, 'BaseType') = 'datetime2' + AND CAST (prv.value AS DATETIME2 (7)) BETWEEN @precedingPartitionBoundary AND @endDateTimeToFilter) + SELECT TOP (@pageSize) Id, + Timestamp, + ResourceId, + ResourceTypeId, + ResourceVersion, + ResourceChangeTypeId + FROM PartitionBoundaries AS p CROSS APPLY (SELECT TOP (@pageSize) Id, + Timestamp, + ResourceId, + ResourceTypeId, + ResourceVersion, + ResourceChangeTypeId + FROM dbo.ResourceChangeData WITH (TABLOCK, HOLDLOCK) + WHERE Id >= @startId + AND $PARTITION.PartitionFunction_ResourceChangeData_Timestamp (Timestamp) = $PARTITION.PartitionFunction_ResourceChangeData_Timestamp (p.PartitionBoundary) + ORDER BY Id ASC) AS rcd + ORDER BY rcd.Id ASC; +END + +GO +CREATE PROCEDURE dbo.GetActiveJobs +@QueueType TINYINT, @GroupId BIGINT=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetActiveJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL'), @st AS DATETIME = getUTCdate(), @JobIds AS BigintList, @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0, @Rows AS INT = 0; +BEGIN TRY + SET @PartitionId = @MaxPartitions * rand(); + WHILE @LookedAtPartitions < @MaxPartitions + BEGIN + IF @GroupId IS NULL + INSERT INTO @JobIds + SELECT JobId + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (0, 1); + ELSE + INSERT INTO @JobIds + SELECT JobId + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND GroupId = @GroupId + AND Status IN (0, 1); + SET @Rows += @@rowcount; + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions += 1; + END + IF @Rows > 0 + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetCommandsForRebuildIndexes +@RebuildClustered BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetCommandsForRebuildIndexes', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId RC=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100), @TblInt AS VARCHAR (100), @Ind AS VARCHAR (200), @IndId AS INT, @Supported AS BIT, @Txt AS VARCHAR (MAX), @Rows AS BIGINT, @Pages AS BIGINT, @ResourceTypeId AS SMALLINT, @IndexesCnt AS INT, @DataComp AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Commands TABLE ( + Tbl VARCHAR (100), + Ind VARCHAR (200), + Txt VARCHAR (MAX), + Pages BIGINT ); + DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY); + DECLARE @Indexes TABLE ( + Ind VARCHAR (200) PRIMARY KEY, + IndId INT ); + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + Supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SELECT TOP 1 @Tbl = name, + @Supported = Supported + FROM @Tables + ORDER BY name; + IF @Supported = 0 + BEGIN + INSERT INTO @Commands + SELECT @Tbl, + name, + 'ALTER INDEX ' + name + ' ON dbo.' + @Tbl + ' REBUILD' + CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = name) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END, + CONVERT (BIGINT, 9e18) + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (is_disabled = 1 + AND index_id > 1 + AND @RebuildClustered = 0 + OR index_id = 1 + AND @RebuildClustered = 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Commands', @Action = 'Insert', @Rows = @@rowcount, @Text = 'Not supported tables with disabled indexes'; + END + ELSE + BEGIN + DELETE @ResourceTypes; + INSERT INTO @ResourceTypes + SELECT CONVERT (SMALLINT, substring(name, charindex('_', name) + 1, 6)) AS ResourceTypeId + FROM sys.sysobjects + WHERE name LIKE @Tbl + '[_]%'; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@ResourceTypes', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @ResourceTypes + ORDER BY ResourceTypeId); + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + SET @Pages = (SELECT dpages + FROM sysindexes + WHERE id = object_id(@TblInt) + AND indid IN (0, 1)); + DELETE @Indexes; + INSERT INTO @Indexes + SELECT name, + index_id + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (index_id > 1 + AND @RebuildClustered = 0 + OR index_id = 1 + AND @RebuildClustered = 1); + SET @IndexesCnt = 0; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @Ind = Ind, + @IndId = IndId + FROM @Indexes + ORDER BY Ind; + IF @IndId = 1 + BEGIN + SET @Txt = 'ALTER INDEX ' + @Ind + ' ON dbo.' + @TblInt + ' REBUILD' + CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = @Ind) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END; + INSERT INTO @Commands + SELECT @TblInt, + @Ind, + @Txt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = @Txt; + END + ELSE + IF NOT EXISTS (SELECT * + FROM sys.indexes + WHERE object_id = object_id(@TblInt) + AND name = @Ind) + BEGIN + EXECUTE dbo.GetIndexCommands @Tbl = @Tbl, @Ind = @Ind, @AddPartClause = 0, @IncludeClustered = 0, @Txt = @Txt OUTPUT; + SET @Txt = replace(@Txt, '[' + @Tbl + ']', @TblInt); + IF @Txt IS NOT NULL + BEGIN + SET @IndexesCnt = @IndexesCnt + 1; + INSERT INTO @Commands + SELECT @TblInt, + @Ind, + @Txt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = @Txt; + END + END + DELETE @Indexes + WHERE Ind = @Ind; + END + IF @IndexesCnt > 1 + BEGIN + INSERT INTO @Commands + SELECT @TblInt, + 'UPDATE STAT', + 'UPDATE STATISTICS dbo.' + @TblInt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = 'Add stats update'; + END + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + END + DELETE @Tables + WHERE name = @Tbl; + END + SELECT Tbl, + Ind, + Txt + FROM @Commands + ORDER BY Pages DESC, Tbl, CASE WHEN Txt LIKE 'UPDATE STAT%' THEN 0 ELSE 1 END; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Commands', @Action = 'Select', @Rows = @@rowcount; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetIndexCommands +@Tbl VARCHAR (100), @Ind VARCHAR (200), @AddPartClause BIT, @IncludeClustered BIT, @Txt VARCHAR (MAX)=NULL OUTPUT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetIndexCommands', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL') + ' Ind=' + isnull(@Ind, 'NULL'), @st AS DATETIME = getUTCdate(); +DECLARE @Indexes TABLE ( + Ind VARCHAR (200) PRIMARY KEY, + Txt VARCHAR (MAX)); +BEGIN TRY + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT Ind, + CASE WHEN is_primary_key = 1 THEN 'ALTER TABLE dbo.[' + Tbl + '] ADD PRIMARY KEY ' + CASE WHEN type = 1 THEN ' CLUSTERED' ELSE '' END ELSE 'CREATE' + CASE WHEN is_unique = 1 THEN ' UNIQUE' ELSE '' END + CASE WHEN type = 1 THEN ' CLUSTERED' ELSE '' END + ' INDEX ' + Ind + ' ON dbo.[' + Tbl + ']' END + ' (' + KeyCols + ')' + IncClause + CASE WHEN filter_def IS NOT NULL THEN ' WHERE ' + filter_def ELSE '' END + CASE WHEN data_comp IS NOT NULL THEN ' WITH (DATA_COMPRESSION = ' + data_comp + ')' ELSE '' END + CASE WHEN @AddPartClause = 1 THEN PartClause ELSE '' END + FROM (SELECT O.Name AS Tbl, + I.Name AS Ind, + isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions AS P + WHERE P.object_id = I.object_id + AND I.index_id = P.index_id), (SELECT NULLIF (PropertyValue, 'NONE') + FROM dbo.IndexProperties + WHERE TableName = O.Name + AND IndexName = I.Name + AND PropertyName = 'DATA_COMPRESSION')) AS data_comp, + replace(replace(replace(replace(I.filter_definition, '[', ''), ']', ''), '(', ''), ')', '') AS filter_def, + I.is_unique, + I.is_primary_key, + I.type, + KeyCols, + CASE WHEN IncCols IS NOT NULL THEN ' INCLUDE (' + IncCols + ')' ELSE '' END AS IncClause, + CASE WHEN EXISTS (SELECT * + FROM sys.partition_schemes AS S + WHERE S.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') THEN ' ON PartitionScheme_ResourceTypeId (ResourceTypeId)' ELSE '' END AS PartClause + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id CROSS APPLY (SELECT string_agg(CASE WHEN IC.key_ordinal > 0 + AND IC.is_included_column = 0 THEN C.name END, ',') WITHIN GROUP (ORDER BY key_ordinal) AS KeyCols, + string_agg(CASE WHEN IC.is_included_column = 1 THEN C.name END, ',') WITHIN GROUP (ORDER BY key_ordinal) AS IncCols + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = IC.object_id + AND C.column_id = IC.column_id + WHERE IC.object_id = I.object_id + AND IC.index_id = I.index_id + GROUP BY IC.object_id, IC.index_id) AS IC + WHERE O.name = @Tbl + AND (@Ind IS NULL + OR I.name = @Ind) + AND (@IncludeClustered = 1 + OR index_id > 1)) AS A; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + IF @Ind IS NULL + SELECT Ind, + Txt + FROM @Indexes; + ELSE + SET @Txt = (SELECT Txt + FROM @Indexes); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = @Txt; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetJobs +@QueueType TINYINT, @JobId BIGINT=NULL, @JobIds BigintList READONLY, @GroupId BIGINT=NULL, @ReturnDefinition BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL'), @st AS DATETIME = getUTCdate(), @PartitionId AS TINYINT = @JobId % 16; +BEGIN TRY + IF @JobId IS NULL + AND @GroupId IS NULL + AND NOT EXISTS (SELECT * + FROM @JobIds) + RAISERROR ('@JobId = NULL and @GroupId = NULL and @JobIds is empty', 18, 127); + IF @JobId IS NOT NULL + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = isnull(@JobId, -1) + AND Status <> 5; + ELSE + IF @GroupId IS NOT NULL + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_GroupId)) + WHERE QueueType = @QueueType + AND GroupId = isnull(@GroupId, -1) + AND Status <> 5; + ELSE + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND JobId IN (SELECT Id + FROM @JobIds) + AND PartitionId = JobId % 16 + AND Status <> 5; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetPartitionedTables +@IncludeNotDisabled BIT, @IncludeNotSupported BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetPartitionedTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId D=' + isnull(CONVERT (VARCHAR, @IncludeNotDisabled), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @IncludeNotSupported), 'NULL'), @st AS DATETIME = getUTCdate(); +DECLARE @NotSupportedTables TABLE ( + id INT PRIMARY KEY); +BEGIN TRY + INSERT INTO @NotSupportedTables + SELECT DISTINCT O.object_id + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') + AND (NOT EXISTS (SELECT * + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = IC.object_id + AND C.column_id = IC.column_id + WHERE IC.object_id = I.object_id + AND IC.index_id = I.index_id + AND IC.key_ordinal > 0 + AND IC.is_included_column = 0 + AND C.name = 'ResourceTypeId') + OR EXISTS (SELECT * + FROM sys.indexes AS NSI + WHERE NSI.object_id = O.object_id + AND NOT EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = NSI.data_space_id + AND name = 'PartitionScheme_ResourceTypeId'))); + SELECT CONVERT (VARCHAR (100), O.name), + CONVERT (BIT, CASE WHEN EXISTS (SELECT * + FROM @NotSupportedTables AS NSI + WHERE NSI.id = O.object_id) THEN 0 ELSE 1 END) + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND I.index_id IN (0, 1) + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') + AND EXISTS (SELECT * + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = I.object_id + AND C.column_id = IC.column_id + AND IC.is_included_column = 0 + AND C.name = 'ResourceTypeId') + AND (@IncludeNotSupported = 1 + OR NOT EXISTS (SELECT * + FROM @NotSupportedTables AS NSI + WHERE NSI.id = O.object_id)) + AND (@IncludeNotDisabled = 1 + OR EXISTS (SELECT * + FROM sys.indexes AS D + WHERE D.object_id = O.object_id + AND D.is_disabled = 1)) + ORDER BY 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetReindexJobById +@id VARCHAR (64) +AS +SET NOCOUNT ON; +SELECT RawJobRecord, + JobVersion +FROM dbo.ReindexJob +WHERE Id = @id; + +GO +CREATE PROCEDURE dbo.GetResources +@ResourceKeys dbo.ResourceKeyList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResources', @InputRows AS INT, @DummyTop AS BIGINT = 9223372036854775807, @NotNullVersionExists AS BIT, @NullVersionExists AS BIT, @MinRT AS SMALLINT, @MaxRT AS SMALLINT; +SELECT @MinRT = min(ResourceTypeId), + @MaxRT = max(ResourceTypeId), + @InputRows = count(*), + @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), + @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) +FROM @ResourceKeys; +DECLARE @Mode AS VARCHAR (100) = 'RT=[' + CONVERT (VARCHAR, @MinRT) + ',' + CONVERT (VARCHAR, @MaxRT) + '] Cnt=' + CONVERT (VARCHAR, @InputRows) + ' NNVE=' + CONVERT (VARCHAR, @NotNullVersionExists) + ' NVE=' + CONVERT (VARCHAR, @NullVersionExists); +BEGIN TRY + IF @NotNullVersionExists = 1 + IF @NullVersionExists = 0 + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + C.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + INNER JOIN + dbo.ResourceTbl AS C WITH (INDEX (IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId)) + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.ResourceId = '' + AND C.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + C.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys + WHERE Version IS NOT NULL) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + INNER JOIN + dbo.ResourceTbl AS C WITH (INDEX (IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId)) + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.ResourceId = '' + AND C.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + C.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys + WHERE Version IS NULL) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + INNER JOIN + dbo.ResourceTbl AS C WITH (INDEX (IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0)) + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.ResourceId = '' + WHERE IsHistory = 0) AS A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + C.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + INNER JOIN + dbo.ResourceTbl AS C WITH (INDEX (IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0)) + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.ResourceId = '' + WHERE IsHistory = 0 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourcesByTransactionId +@TransactionId BIGINT, @IncludeHistory BIT=0, @ReturnResourceKeysOnly BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId) + ' H=' + CONVERT (VARCHAR, @IncludeHistory), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807, @TypeId AS SMALLINT; +BEGIN TRY + DECLARE @Types TABLE ( + TypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + DECLARE @Keys TABLE ( + TypeId SMALLINT, + SurrogateId BIGINT PRIMARY KEY (TypeId, SurrogateId)); + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @TypeId = (SELECT TOP 1 TypeId + FROM @Types + ORDER BY TypeId); + INSERT INTO @Keys + SELECT @TypeId, + ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @TypeId + AND TransactionId = @TransactionId; + DELETE @Types + WHERE TypeId = @TypeId; + END + IF @ReturnResourceKeysOnly = 0 + SELECT ResourceTypeId, + ResourceId, + ResourceSurrogateId, + Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + RequestMethod, + TransactionId, + OffsetInFile + FROM (SELECT TOP (@DummyTop) * + FROM @Keys) AS A + INNER JOIN + dbo.Resource AS B + ON ResourceTypeId = TypeId + AND ResourceSurrogateId = SurrogateId + WHERE IsHistory = 0 + OR @IncludeHistory = 1 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT ResourceTypeId, + ResourceId, + ResourceSurrogateId, + Version, + IsDeleted + FROM (SELECT TOP (@DummyTop) * + FROM @Keys) AS A + INNER JOIN + dbo.Resource AS B + ON ResourceTypeId = TypeId + AND ResourceSurrogateId = SurrogateId + WHERE IsHistory = 0 + OR @IncludeHistory = 1 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange +@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @GlobalEndId BIGINT=NULL, @IncludeHistory BIT=0, @IncludeDeleted BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetResourcesByTypeAndSurrogateIdRange', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' GE=' + isnull(CONVERT (VARCHAR, @GlobalEndId), 'NULL') + ' HI=' + isnull(CONVERT (VARCHAR, @IncludeHistory), 'NULL') + ' DE' + isnull(CONVERT (VARCHAR, @IncludeDeleted), 'NULL'), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807; +BEGIN TRY + DECLARE @ResourceIds TABLE ( + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY); + DECLARE @SurrogateIds TABLE ( + MaxSurrogateId BIGINT PRIMARY KEY); + IF @GlobalEndId IS NOT NULL + AND @IncludeHistory = 0 + BEGIN + INSERT INTO @ResourceIds + SELECT DISTINCT ResourceId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + IF @@rowcount > 0 + INSERT INTO @SurrogateIds + SELECT ResourceSurrogateId + FROM (SELECT ResourceId, + ResourceSurrogateId, + row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) AS RowId + FROM dbo.Resource WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId + FROM @ResourceIds) + AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId) AS A + WHERE RowId = 1 + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + END + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource, + TransactionId, + OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND (IsHistory = 0 + OR @IncludeHistory = 1) + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource, + TransactionId, + OffsetInFile + FROM @SurrogateIds + INNER JOIN + dbo.Resource + ON ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceSearchParamStats +@Table VARCHAR (100)=NULL, @ResourceTypeId SMALLINT=NULL, @SearchParamId SMALLINT=NULL +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'T=' + isnull(@Table, 'NULL') + ' RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' SP=' + isnull(CONVERT (VARCHAR, @SearchParamId), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + SELECT T.name AS TableName, + S.name AS StatsName, + db_name() AS DatabaseName + FROM sys.stats AS S + INNER JOIN + sys.tables AS T + ON T.object_id = S.object_id + WHERE T.name LIKE '%SearchParam' + AND T.name <> 'SearchParam' + AND S.name LIKE 'ST[_]%' + AND (T.name LIKE @Table + OR @Table IS NULL) + AND (S.name LIKE '%ResourceTypeId[_]' + CONVERT (VARCHAR, @ResourceTypeId) + '[_]%' + OR @ResourceTypeId IS NULL) + AND (S.name LIKE '%SearchParamId[_]' + CONVERT (VARCHAR, @SearchParamId) + OR @SearchParamId IS NULL); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Rows = @@rowcount, @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceSurrogateIdRanges +@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @RangeSize INT, @NumberOfRanges INT=100, @Up BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetResourceSurrogateIdRanges', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' R=' + isnull(CONVERT (VARCHAR, @RangeSize), 'NULL') + ' UP=' + isnull(CONVERT (VARCHAR, @Up), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + IF @Up = 1 + SELECT RangeId, + min(ResourceSurrogateId), + max(ResourceSurrogateId), + count(*) + FROM (SELECT isnull(CONVERT (INT, (row_number() OVER (ORDER BY ResourceSurrogateId) - 1) / @RangeSize), 0) AS RangeId, + ResourceSurrogateId + FROM (SELECT TOP (@RangeSize * @NumberOfRanges) ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId >= @StartId + AND ResourceSurrogateId <= @EndId + ORDER BY ResourceSurrogateId) AS A) AS A + GROUP BY RangeId + OPTION (MAXDOP 1); + ELSE + SELECT RangeId, + min(ResourceSurrogateId), + max(ResourceSurrogateId), + count(*) + FROM (SELECT isnull(CONVERT (INT, (row_number() OVER (ORDER BY ResourceSurrogateId) - 1) / @RangeSize), 0) AS RangeId, + ResourceSurrogateId + FROM (SELECT TOP (@RangeSize * @NumberOfRanges) ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId >= @StartId + AND ResourceSurrogateId <= @EndId + ORDER BY ResourceSurrogateId DESC) AS A) AS A + GROUP BY RangeId + OPTION (MAXDOP 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceVersions +@ResourceDateKeys dbo.ResourceDateKeyList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResourceVersions', @Mode AS VARCHAR (100) = 'Rows=' + CONVERT (VARCHAR, (SELECT count(*) + FROM @ResourceDateKeys)), @DummyTop AS BIGINT = 9223372036854775807; +BEGIN TRY + SELECT A.ResourceTypeId, + A.ResourceId, + A.ResourceSurrogateId, + CASE WHEN D.Version IS NOT NULL THEN 0 WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex ELSE isnull(M.Version, 0) - ResourceIndex END AS Version, + isnull(D.Version, 0) AS MatchedVersion, + D.RawResource AS MatchedRawResource, + D.TransactionId AS MatchedTransactionId, + D.OffsetInFile AS MatchedOffsetInFile + FROM (SELECT TOP (@DummyTop) *, + CONVERT (INT, row_number() OVER (PARTITION BY ResourceTypeId, ResourceId ORDER BY ResourceSurrogateId DESC)) AS ResourceIndex + FROM @ResourceDateKeys) AS A OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version > 0 + AND B.ResourceSurrogateId < A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId DESC) AS L OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version > 0 + AND B.ResourceSurrogateId > A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId) AS U OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version < 0 + ORDER BY B.Version) AS M OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) AS D + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetSearchParamStatuses +AS +SET NOCOUNT ON; +SELECT SearchParamId, + Uri, + Status, + LastUpdated, + IsPartiallySupported +FROM dbo.SearchParam; + +GO +CREATE PROCEDURE dbo.GetTransactions +@StartNotInclusiveTranId BIGINT, @EndInclusiveTranId BIGINT, @EndDate DATETIME=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'ST=' + CONVERT (VARCHAR, @StartNotInclusiveTranId) + ' ET=' + CONVERT (VARCHAR, @EndInclusiveTranId) + ' ED=' + isnull(CONVERT (VARCHAR, @EndDate, 121), 'NULL'), @st AS DATETIME = getUTCdate(); +IF @EndDate IS NULL + SET @EndDate = getUTCdate(); +SELECT SurrogateIdRangeFirstValue, + VisibleDate, + InvisibleHistoryRemovedDate +FROM dbo.Transactions +WHERE SurrogateIdRangeFirstValue > @StartNotInclusiveTranId + AND SurrogateIdRangeFirstValue <= @EndInclusiveTranId + AND EndDate <= @EndDate +ORDER BY SurrogateIdRangeFirstValue; +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; + +GO +CREATE PROCEDURE dbo.GetUsedResourceTypes +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetUsedResourceTypes', @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(); +BEGIN TRY + SELECT ResourceTypeId, + Name + FROM dbo.ResourceType AS A + WHERE EXISTS (SELECT * + FROM dbo.Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.HardDeleteResource +@ResourceTypeId SMALLINT, @ResourceId VARCHAR (64), @KeepCurrentVersion BIT, @IsResourceChangeCaptureEnabled BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'RT=' + CONVERT (VARCHAR, @ResourceTypeId) + ' R=' + @ResourceId + ' V=' + CONVERT (VARCHAR, @KeepCurrentVersion) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled), @st AS DATETIME = getUTCdate(), @TransactionId AS BIGINT; +BEGIN TRY + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUTPUT; + IF @KeepCurrentVersion = 0 + BEGIN TRANSACTION; + DECLARE @SurrogateIds TABLE ( + ResourceSurrogateId BIGINT NOT NULL); + IF @IsResourceChangeCaptureEnabled = 1 + AND NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'InvisibleHistory.IsEnabled' + AND Number = 0) + UPDATE dbo.Resource + SET IsDeleted = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1) + AND RawResource <> 0xF; + ELSE + DELETE dbo.Resource + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1) + AND RawResource <> 0xF; + IF @KeepCurrentVersion = 0 + BEGIN + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ResourceWriteClaim AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE dbo.ReferenceSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenText AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.StringSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.UriSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.NumberSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.QuantitySearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.DateTimeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ReferenceTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenDateTimeCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenQuantityCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenStringCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenNumberNumberCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + END + IF @@trancount > 0 + COMMIT TRANSACTION; + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.InitDefrag +@QueueType TINYINT, @GroupId BIGINT, @DefragItems INT=NULL OUTPUT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'InitDefrag', @st AS DATETIME = getUTCdate(), @ObjectId AS INT, @msg AS VARCHAR (1000), @Rows AS INT, @MinFragPct AS INT = isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'Defrag.MinFragPct'), 10), @MinSizeGB AS FLOAT = isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'Defrag.MinSizeGB'), 0.1), @DefinitionsSorted AS StringList; +DECLARE @Mode AS VARCHAR (200) = 'G=' + CONVERT (VARCHAR, @GroupId) + ' MF=' + CONVERT (VARCHAR, @MinFragPct) + ' MS=' + CONVERT (VARCHAR, @MinSizeGB); +DECLARE @Definitions AS TABLE ( + Def VARCHAR (900) PRIMARY KEY, + FragGB FLOAT ); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + SELECT * + INTO #filter + FROM (SELECT object_id, + sum(reserved_page_count * 8.0 / 1024 / 1024) AS ReservedGB + FROM sys.dm_db_partition_stats AS A + WHERE object_id IN (SELECT object_id + FROM sys.objects + WHERE type = 'U' + AND name NOT IN ('EventLog')) + GROUP BY object_id) AS A + WHERE ReservedGB > @MinSizeGB; + WHILE EXISTS (SELECT * + FROM #filter) + BEGIN + SET @ObjectId = (SELECT TOP 1 object_id + FROM #filter + ORDER BY ReservedGB DESC); + INSERT INTO @Definitions + SELECT object_name(@ObjectId) + ';' + I.name + ';' + CONVERT (VARCHAR, partition_number) + ';' + CONVERT (VARCHAR, CASE WHEN EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id) THEN 1 ELSE 0 END) + ';' + CONVERT (VARCHAR, (SELECT sum(reserved_page_count) + FROM sys.dm_db_partition_stats AS S + WHERE S.object_id = A.object_id + AND S.index_id = A.index_id + AND S.partition_number = A.partition_number) * 8.0 / 1024 / 1024), + FragGB + FROM (SELECT object_id, + index_id, + partition_number, + A.avg_fragmentation_in_percent * A.page_count * 8.0 / 1024 / 1024 / 100 AS FragGB + FROM sys.dm_db_index_physical_stats(db_id(), @ObjectId, NULL, NULL, 'LIMITED') AS A + WHERE index_id > 0 + AND avg_fragmentation_in_percent >= @MinFragPct + AND A.page_count > 500) AS A + INNER JOIN + sys.indexes AS I + ON I.object_id = A.object_id + AND I.index_id = A.index_id; + SET @Rows = @@rowcount; + SET @msg = object_name(@ObjectId); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Run', @Mode = @Mode, @Target = '@Definitions', @Action = 'Insert', @Rows = @Rows, @Text = @msg; + DELETE #filter + WHERE object_id = @ObjectId; + END + INSERT INTO @DefinitionsSorted + SELECT Def + ';' + CONVERT (VARCHAR, FragGB) + FROM @Definitions + ORDER BY FragGB DESC; + SET @DefragItems = @@rowcount; + IF @DefragItems > 0 + EXECUTE dbo.EnqueueJobs @QueueType = @QueueType, @Definitions = @DefinitionsSorted, @GroupId = @GroupId, @ForceOneActiveJobGroup = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.InitializeIndexProperties +AS +SET NOCOUNT ON; +INSERT INTO dbo.IndexProperties (TableName, IndexName, PropertyName, PropertyValue) +SELECT Tbl, + Ind, + 'DATA_COMPRESSION', + isnull(data_comp, 'NONE') +FROM (SELECT O.Name AS Tbl, + I.Name AS Ind, + (SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions AS P + WHERE P.object_id = I.object_id + AND I.index_id = P.index_id) AS data_comp + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId')) AS A +WHERE NOT EXISTS (SELECT * + FROM dbo.IndexProperties + WHERE TableName = Tbl + AND IndexName = Ind); + +GO +CREATE PROCEDURE dbo.LogEvent +@Process VARCHAR (100), @Status VARCHAR (10), @Mode VARCHAR (200)=NULL, @Action VARCHAR (20)=NULL, @Target VARCHAR (100)=NULL, @Rows BIGINT=NULL, @Start DATETIME=NULL, @Text NVARCHAR (3500)=NULL, @EventId BIGINT=NULL OUTPUT, @Retry INT=NULL +AS +SET NOCOUNT ON; +DECLARE @ErrorNumber AS INT = error_number(), @ErrorMessage AS VARCHAR (1000) = '', @TranCount AS INT = @@trancount, @DoWork AS BIT = 0, @NumberAdded AS BIT; +IF @ErrorNumber IS NOT NULL + OR @Status IN ('Warn', 'Error') + SET @DoWork = 1; +IF @DoWork = 0 + SET @DoWork = CASE WHEN EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = isnull(@Process, '') + AND Char = 'LogEvent') THEN 1 ELSE 0 END; +IF @DoWork = 0 + RETURN; +IF @ErrorNumber IS NOT NULL + SET @ErrorMessage = CASE WHEN @Retry IS NOT NULL THEN 'Retry ' + CONVERT (VARCHAR, @Retry) + ', ' ELSE '' END + 'Error ' + CONVERT (VARCHAR, error_number()) + ': ' + CONVERT (VARCHAR (1000), error_message()) + ', Level ' + CONVERT (VARCHAR, error_severity()) + ', State ' + CONVERT (VARCHAR, error_state()) + CASE WHEN error_procedure() IS NOT NULL THEN ', Procedure ' + error_procedure() ELSE '' END + ', Line ' + CONVERT (VARCHAR, error_line()); +IF @TranCount > 0 + AND @ErrorNumber IS NOT NULL + ROLLBACK; +IF databasepropertyex(db_name(), 'UpdateAbility') = 'READ_WRITE' + BEGIN + INSERT INTO dbo.EventLog (Process, Status, Mode, Action, Target, Rows, Milliseconds, EventDate, EventText, SPID, HostName) + SELECT @Process, + @Status, + @Mode, + @Action, + @Target, + @Rows, + datediff(millisecond, @Start, getUTCdate()), + getUTCdate() AS EventDate, + CASE WHEN @ErrorNumber IS NULL THEN @Text ELSE @ErrorMessage + CASE WHEN isnull(@Text, '') <> '' THEN '. ' + @Text ELSE '' END END AS Text, + @@SPID, + host_name() AS HostName; + SET @EventId = scope_identity(); + END +IF @TranCount > 0 + AND @ErrorNumber IS NOT NULL + BEGIN TRANSACTION; + +GO +CREATE PROCEDURE dbo.LogSchemaMigrationProgress +@message VARCHAR (MAX) +AS +INSERT INTO dbo.SchemaMigrationProgress (Message) +VALUES (@message); + +GO +CREATE PROCEDURE dbo.MergeResources +@AffectedRows INT=0 OUTPUT, @RaiseExceptionOnConflict BIT=1, @IsResourceChangeCaptureEnabled BIT=0, @TransactionId BIGINT=NULL, @SingleTransaction BIT=1, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParms dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0, @RT AS SMALLINT, @NewIdsCount AS INT, @FirstIdInt AS BIGINT; +DECLARE @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) + FROM @Resources), 'Input=Empty'); +SET @Mode += ' E=' + CONVERT (VARCHAR, @RaiseExceptionOnConflict) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled) + ' IT=' + CONVERT (VARCHAR, @InitialTranCount) + ' T=' + isnull(CONVERT (VARCHAR, @TransactionId), 'NULL'); +SET @AffectedRows = 0; +BEGIN TRY + DECLARE @RTs AS TABLE ( + ResourceTypeId SMALLINT NOT NULL PRIMARY KEY); + DECLARE @InputIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @ExistingIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @InsertIds AS TABLE ( + ResourceIndex INT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL); + DECLARE @InsertedIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @ResourcesWithIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + IsDeleted BIT NOT NULL, + IsHistory BIT NOT NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + SearchParamHash VARCHAR (64) NULL, + OffsetInFile INT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), + UNIQUE (ResourceTypeId, ResourceIdInt, Version)); + DECLARE @ReferenceSearchParamsWithIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceIdInt BIGINT NOT NULL, + ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt)); + INSERT INTO @InputIds + SELECT DISTINCT ReferenceResourceTypeId, + ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NOT NULL; + INSERT INTO @RTs + SELECT DISTINCT ResourceTypeId + FROM @InputIds; + WHILE EXISTS (SELECT * + FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId + FROM @RTs); + INSERT INTO @ExistingIds (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT @RT, + ResourceIdInt, + A.ResourceId + FROM (SELECT * + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId; + DELETE @InsertIds; + INSERT INTO @InsertIds (ResourceIndex, ResourceId) + SELECT row_number() OVER (ORDER BY ResourceId) - 1 AS RowId, + ResourceId + FROM (SELECT ResourceId + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + WHERE NOT EXISTS (SELECT * + FROM @ExistingIds AS B + WHERE B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId); + SET @NewIdsCount = (SELECT count(*) + FROM @InsertIds); + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; + INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, + ResourceIndex + @FirstIdInt, + ResourceId + FROM @InsertIds; + END + DELETE @RTs + WHERE ResourceTypeId = @RT; + END + INSERT INTO @ReferenceSearchParamsWithIds (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT A.ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + isnull(C.ResourceIdInt, B.ResourceIdInt), + ReferenceResourceVersion + FROM @ReferenceSearchParams AS A + LEFT OUTER JOIN + @InsertedIds AS B + ON B.ResourceTypeId = A.ReferenceResourceTypeId + AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN + @ExistingIds AS C + ON C.ResourceTypeId = A.ReferenceResourceTypeId + AND C.ResourceId = A.ReferenceResourceId; + DELETE @InputIds; + DELETE @RTs; + DELETE @InsertedIds; + DELETE @ExistingIds; + INSERT INTO @InputIds + SELECT ResourceTypeId, + ResourceId + FROM @Resources + GROUP BY ResourceTypeId, ResourceId; + INSERT INTO @RTs + SELECT DISTINCT ResourceTypeId + FROM @InputIds; + WHILE EXISTS (SELECT * + FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId + FROM @RTs); + INSERT INTO @ExistingIds (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT @RT, + ResourceIdInt, + A.ResourceId + FROM (SELECT * + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId; + DELETE @InsertIds; + INSERT INTO @InsertIds (ResourceIndex, ResourceId) + SELECT row_number() OVER (ORDER BY ResourceId) - 1 AS RowId, + ResourceId + FROM (SELECT ResourceId + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + WHERE NOT EXISTS (SELECT * + FROM @ExistingIds AS B + WHERE B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId); + SET @NewIdsCount = (SELECT count(*) + FROM @InsertIds); + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; + INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, + ResourceIndex + @FirstIdInt, + ResourceId + FROM @InsertIds; + END + DELETE @RTs + WHERE ResourceTypeId = @RT; + END + INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile) + SELECT A.ResourceTypeId, + isnull(C.ResourceIdInt, B.ResourceIdInt), + Version, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + OffsetInFile + FROM @Resources AS A + LEFT OUTER JOIN + @InsertedIds AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN + @ExistingIds AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceId = A.ResourceId; + DECLARE @Existing AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)); + DECLARE @ResourceInfos AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL, + Version INT NOT NULL, + KeepHistory BIT NOT NULL, + PreviousVersion INT NULL, + PreviousSurrogateId BIGINT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)); + DECLARE @PreviousSurrogateIds AS TABLE ( + TypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL PRIMARY KEY (TypeId, SurrogateId), + KeepHistory BIT ); + IF @SingleTransaction = 0 + AND isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'MergeResources.NoTransaction.IsEnabled'), 0) = 0 + SET @SingleTransaction = 1; + SET @Mode += ' ST=' + CONVERT (VARCHAR, @SingleTransaction); + IF @InitialTranCount = 0 + BEGIN + IF EXISTS (SELECT * + FROM @Resources AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId) + BEGIN + BEGIN TRANSACTION; + INSERT INTO @Existing (ResourceTypeId, SurrogateId) + SELECT B.ResourceTypeId, + B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * + FROM @Resources) AS A + INNER JOIN + dbo.Resource AS B WITH (ROWLOCK, HOLDLOCK) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0 + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + IF @@rowcount = (SELECT count(*) + FROM @Resources) + SET @IsRetry = 1; + IF @IsRetry = 0 + COMMIT TRANSACTION; + END + END + SET @Mode += ' R=' + CONVERT (VARCHAR, @IsRetry); + IF @SingleTransaction = 1 + AND @@trancount = 0 + BEGIN TRANSACTION; + IF @IsRetry = 0 + BEGIN + INSERT INTO @ResourceInfos (ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId) + SELECT A.ResourceTypeId, + A.ResourceSurrogateId, + A.Version, + A.KeepHistory, + B.Version, + B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * + FROM @Resources + WHERE HasVersionToCompare = 1) AS A + LEFT OUTER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.IsHistory = 0 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + IF @RaiseExceptionOnConflict = 1 + AND EXISTS (SELECT * + FROM @ResourceInfos + WHERE PreviousVersion IS NOT NULL + AND Version <= PreviousVersion) + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + INSERT INTO @PreviousSurrogateIds + SELECT ResourceTypeId, + PreviousSurrogateId, + KeepHistory + FROM @ResourceInfos + WHERE PreviousSurrogateId IS NOT NULL; + IF @@rowcount > 0 + BEGIN + UPDATE dbo.Resource + SET IsHistory = 1 + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 1); + SET @AffectedRows += @@rowcount; + IF @IsResourceChangeCaptureEnabled = 1 + AND NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'InvisibleHistory.IsEnabled' + AND Number = 0) + UPDATE dbo.Resource + SET IsHistory = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 0); + ELSE + DELETE dbo.Resource + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 0); + SET @AffectedRows += @@rowcount; + DELETE dbo.ResourceWriteClaim + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.ReferenceSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenText + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.StringSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.UriSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.NumberSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.QuantitySearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.DateTimeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.ReferenceTokenCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenTokenCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenDateTimeCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenQuantityCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenStringCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenNumberNumberCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + END + INSERT INTO dbo.ResourceTbl (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile) + SELECT ResourceTypeId, + ResourceIdInt, + Version, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + @TransactionId, + OffsetInFile + FROM @ResourcesWithIds; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM @ResourceWriteClaims; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceSearchParamTbl (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceIdInt, + ReferenceResourceVersion + FROM @ReferenceSearchParamsWithIds; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM @TokenSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM @TokenTexts; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM @StringSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM @UriSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM @NumberSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM @QuantitySearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM @DateTimeSearchParms; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM @TokenTokenCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM @TokenQuantityCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM @TokenStringCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM @TokenNumberNumberCompositeSearchParams; + SET @AffectedRows += @@rowcount; + END + ELSE + BEGIN + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceWriteClaims) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.ResourceWriteClaim AS C + WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceSearchParamTbl (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT A.ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceIdInt, + ReferenceResourceVersion + FROM (SELECT TOP (@DummyTop) * + FROM @ReferenceSearchParamsWithIds) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.ReferenceSearchParamTbl AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM (SELECT TOP (@DummyTop) * + FROM @TokenSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM (SELECT TOP (@DummyTop) * + FROM @TokenTexts) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM (SELECT TOP (@DummyTop) * + FROM @StringSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenText AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM (SELECT TOP (@DummyTop) * + FROM @UriSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.UriSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM (SELECT TOP (@DummyTop) * + FROM @NumberSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.NumberSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM (SELECT TOP (@DummyTop) * + FROM @QuantitySearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.QuantitySearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM (SELECT TOP (@DummyTop) * + FROM @DateTimeSearchParms) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @ReferenceTokenCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.DateTimeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenTokenCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenTokenCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenDateTimeCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenDateTimeCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenQuantityCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenQuantityCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenStringCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenStringCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM (SELECT TOP (@DummyTop) * + FROM @TokenNumberNumberCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenNumberNumberCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + END + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.CaptureResourceIdsForChanges @Resources; + IF @TransactionId IS NOT NULL + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + IF @InitialTranCount = 0 + AND @@trancount > 0 + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 + AND @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + IF @RaiseExceptionOnConflict = 1 + AND error_number() IN (2601, 2627) + AND error_message() LIKE '%''dbo.Resource%' + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesAdvanceTransactionVisibility +@AffectedRows INT=0 OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(), @msg AS VARCHAR (1000), @MaxTransactionId AS BIGINT, @MinTransactionId AS BIGINT, @MinNotCompletedTransactionId AS BIGINT, @CurrentTransactionId AS BIGINT; +SET @AffectedRows = 0; +BEGIN TRY + EXECUTE dbo.MergeResourcesGetTransactionVisibility @MinTransactionId OUTPUT; + SET @MinTransactionId += 1; + SET @CurrentTransactionId = (SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + ORDER BY SurrogateIdRangeFirstValue DESC); + SET @MinNotCompletedTransactionId = isnull((SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsCompleted = 0 + AND SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + ORDER BY SurrogateIdRangeFirstValue), @CurrentTransactionId + 1); + SET @MaxTransactionId = (SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsCompleted = 1 + AND SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + AND SurrogateIdRangeFirstValue < @MinNotCompletedTransactionId + ORDER BY SurrogateIdRangeFirstValue DESC); + IF @MaxTransactionId >= @MinTransactionId + BEGIN + UPDATE A + SET IsVisible = 1, + VisibleDate = getUTCdate() + FROM dbo.Transactions AS A WITH (INDEX (1)) + WHERE SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + AND SurrogateIdRangeFirstValue <= @MaxTransactionId; + SET @AffectedRows += @@rowcount; + END + SET @msg = 'Min=' + CONVERT (VARCHAR, @MinTransactionId) + ' C=' + CONVERT (VARCHAR, @CurrentTransactionId) + ' MinNC=' + CONVERT (VARCHAR, @MinNotCompletedTransactionId) + ' Max=' + CONVERT (VARCHAR, @MaxTransactionId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows, @Text = @msg; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesBeginTransaction +@Count INT, @TransactionId BIGINT OUTPUT, @SequenceRangeFirstValue INT=NULL OUTPUT, @HeartbeatDate DATETIME=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesBeginTransaction', @Mode AS VARCHAR (200) = 'Cnt=' + CONVERT (VARCHAR, @Count), @st AS DATETIME = getUTCdate(), @FirstValueVar AS SQL_VARIANT, @LastValueVar AS SQL_VARIANT; +BEGIN TRY + SET @TransactionId = NULL; + IF @@trancount > 0 + RAISERROR ('MergeResourcesBeginTransaction cannot be called inside outer transaction.', 18, 127); + SET @FirstValueVar = NULL; + WHILE @FirstValueVar IS NULL + BEGIN + EXECUTE sys.sp_sequence_get_range @sequence_name = 'dbo.ResourceSurrogateIdUniquifierSequence', @range_size = @Count, @range_first_value = @FirstValueVar OUTPUT, @range_last_value = @LastValueVar OUTPUT; + SET @SequenceRangeFirstValue = CONVERT (INT, @FirstValueVar); + IF @SequenceRangeFirstValue > CONVERT (INT, @LastValueVar) + SET @FirstValueVar = NULL; + END + SET @TransactionId = datediff_big(millisecond, '0001-01-01', sysUTCdatetime()) * 80000 + @SequenceRangeFirstValue; + INSERT INTO dbo.Transactions (SurrogateIdRangeFirstValue, SurrogateIdRangeLastValue, HeartbeatDate) + SELECT @TransactionId, + @TransactionId + @Count - 1, + isnull(@HeartbeatDate, getUTCdate()); +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesCommitTransaction +@TransactionId BIGINT, @FailureReason VARCHAR (MAX)=NULL, @OverrideIsControlledByClientCheck BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesCommitTransaction', @st AS DATETIME = getUTCdate(), @InitialTranCount AS INT = @@trancount, @IsCompletedBefore AS BIT, @Rows AS INT, @msg AS VARCHAR (1000); +DECLARE @Mode AS VARCHAR (200) = 'TR=' + CONVERT (VARCHAR, @TransactionId) + ' OC=' + isnull(CONVERT (VARCHAR, @OverrideIsControlledByClientCheck), 'NULL'); +BEGIN TRY + IF @InitialTranCount = 0 + BEGIN TRANSACTION; + UPDATE dbo.Transactions + SET IsCompleted = 1, + @IsCompletedBefore = IsCompleted, + EndDate = getUTCdate(), + IsSuccess = CASE WHEN @FailureReason IS NULL THEN 1 ELSE 0 END, + FailureReason = @FailureReason + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND (IsControlledByClient = 1 + OR @OverrideIsControlledByClientCheck = 1); + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + SET @msg = 'Transaction [' + CONVERT (VARCHAR (20), @TransactionId) + '] is not controlled by client or does not exist.'; + RAISERROR (@msg, 18, 127); + END + IF @IsCompletedBefore = 1 + BEGIN + IF @InitialTranCount = 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Target = '@IsCompletedBefore', @Text = '=1'; + RETURN; + END + IF @InitialTranCount = 0 + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 + AND @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory +@TransactionId BIGINT, @AffectedRows INT=NULL OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(), @TypeId AS SMALLINT; +SET @AffectedRows = 0; +BEGIN TRY + DECLARE @Types TABLE ( + TypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @TypeId = (SELECT TOP 1 TypeId + FROM @Types + ORDER BY TypeId); + DELETE dbo.Resource + WHERE ResourceTypeId = @TypeId + AND HistoryTransactionId = @TransactionId + AND RawResource = 0xF; + SET @AffectedRows += @@rowcount; + DELETE @Types + WHERE TypeId = @TypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesGetTimeoutTransactions +@TimeoutSec INT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TimeoutSec), @st AS DATETIME = getUTCdate(), @MinTransactionId AS BIGINT; +BEGIN TRY + EXECUTE dbo.MergeResourcesGetTransactionVisibility @MinTransactionId OUTPUT; + SELECT SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE SurrogateIdRangeFirstValue > @MinTransactionId + AND IsCompleted = 0 + AND datediff(second, HeartbeatDate, getUTCdate()) > @TimeoutSec + ORDER BY SurrogateIdRangeFirstValue; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesGetTransactionVisibility +@TransactionId BIGINT OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(); +SET @TransactionId = isnull((SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsVisible = 1 + ORDER BY SurrogateIdRangeFirstValue DESC), -1); +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount, @Text = @TransactionId; + +GO +CREATE PROCEDURE dbo.MergeResourcesPutTransactionHeartbeat +@TransactionId BIGINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesPutTransactionHeartbeat', @Mode AS VARCHAR (100) = 'TR=' + CONVERT (VARCHAR, @TransactionId); +BEGIN TRY + UPDATE dbo.Transactions + SET HeartbeatDate = getUTCdate() + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND IsControlledByClient = 1; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesPutTransactionInvisibleHistory +@TransactionId BIGINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'TR=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(); +BEGIN TRY + UPDATE dbo.Transactions + SET InvisibleHistoryRemovedDate = getUTCdate() + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND InvisibleHistoryRemovedDate IS NULL; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobCancelation +@QueueType TINYINT, @GroupId BIGINT=NULL, @JobId BIGINT=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobCancelation', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL') + ' J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL'), @st AS DATETIME = getUTCdate(), @Rows AS INT, @PartitionId AS TINYINT = @JobId % 16; +BEGIN TRY + IF @JobId IS NULL + AND @GroupId IS NULL + RAISERROR ('@JobId = NULL and @GroupId = NULL', 18, 127); + IF @JobId IS NOT NULL + BEGIN + UPDATE dbo.JobQueue + SET Status = 4, + EndDate = getUTCdate(), + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 0; + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + UPDATE dbo.JobQueue + SET CancelRequested = 1 + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1; + SET @Rows = @@rowcount; + END + END + ELSE + BEGIN + UPDATE dbo.JobQueue + SET Status = 4, + EndDate = getUTCdate(), + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()) + WHERE QueueType = @QueueType + AND GroupId = @GroupId + AND Status = 0; + SET @Rows = @@rowcount; + UPDATE dbo.JobQueue + SET CancelRequested = 1 + WHERE QueueType = @QueueType + AND GroupId = @GroupId + AND Status = 1; + SET @Rows += @@rowcount; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobHeartbeat +@QueueType TINYINT, @JobId BIGINT, @Version BIGINT, @Data BIGINT=NULL, @CancelRequested BIT=0 OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobHeartbeat', @Mode AS VARCHAR (100), @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT = @JobId % 16; +SET @Mode = 'Q=' + CONVERT (VARCHAR, @QueueType) + ' J=' + CONVERT (VARCHAR, @JobId) + ' P=' + CONVERT (VARCHAR, @PartitionId) + ' V=' + CONVERT (VARCHAR, @Version) + ' D=' + isnull(CONVERT (VARCHAR, @Data), 'NULL'); +BEGIN TRY + UPDATE dbo.JobQueue + SET @CancelRequested = CancelRequested, + HeartbeatDate = getUTCdate() + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1 + AND Version = @Version; + SET @Rows = @@rowcount; + IF @Rows = 0 + AND NOT EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Version = @Version + AND Status IN (2, 3, 4)) + BEGIN + IF EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId) + THROW 50412, 'Precondition failed', 1; + ELSE + THROW 50404, 'Job record not found', 1; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobStatus +@QueueType TINYINT, @JobId BIGINT, @Version BIGINT, @Failed BIT, @Data BIGINT, @FinalResult VARCHAR (MAX), @RequestCancellationOnFailure BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobStatus', @Mode AS VARCHAR (100), @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT = @JobId % 16, @GroupId AS BIGINT; +SET @Mode = 'Q=' + CONVERT (VARCHAR, @QueueType) + ' J=' + CONVERT (VARCHAR, @JobId) + ' P=' + CONVERT (VARCHAR, @PartitionId) + ' V=' + CONVERT (VARCHAR, @Version) + ' F=' + CONVERT (VARCHAR, @Failed) + ' R=' + isnull(@FinalResult, 'NULL'); +BEGIN TRY + UPDATE dbo.JobQueue + SET EndDate = getUTCdate(), + Status = CASE WHEN @Failed = 1 THEN 3 WHEN CancelRequested = 1 THEN 4 ELSE 2 END, + Data = @Data, + Result = @FinalResult, + @GroupId = GroupId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1 + AND Version = @Version; + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + SET @GroupId = (SELECT GroupId + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Version = @Version + AND Status IN (2, 3, 4)); + IF @GroupId IS NULL + IF EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId) + THROW 50412, 'Precondition failed', 1; + ELSE + THROW 50404, 'Job record not found', 1; + END + IF @Failed = 1 + AND @RequestCancellationOnFailure = 1 + EXECUTE dbo.PutJobCancelation @QueueType = @QueueType, @GroupId = @GroupId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.RemovePartitionFromResourceChanges_2 +@partitionNumberToSwitchOut INT, @partitionBoundaryToMerge DATETIME2 (7) +AS +BEGIN + TRUNCATE TABLE dbo.ResourceChangeDataStaging; + ALTER TABLE dbo.ResourceChangeData SWITCH PARTITION @partitionNumberToSwitchOut TO dbo.ResourceChangeDataStaging; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + MERGE RANGE (@partitionBoundaryToMerge); + TRUNCATE TABLE dbo.ResourceChangeDataStaging; +END + +GO +CREATE PROCEDURE dbo.SwitchPartitionsIn +@Tbl VARCHAR (100) +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsIn', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL'), @st AS DATETIME = getUTCdate(), @ResourceTypeId AS SMALLINT, @Rows AS BIGINT, @Txt AS VARCHAR (1000), @TblInt AS VARCHAR (100), @Ind AS VARCHAR (200), @IndId AS INT, @DataComp AS VARCHAR (100); +DECLARE @Indexes TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200)); +DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT index_id, + name + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND is_disabled = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @IndId = IndId, + @Ind = name + FROM @Indexes + ORDER BY IndId; + SET @DataComp = CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = @Ind) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END; + SET @Txt = 'IF EXISTS (SELECT * FROM sys.indexes WHERE object_id = object_id(''' + @Tbl + ''') AND name = ''' + @Ind + ''' AND is_disabled = 1) ALTER INDEX ' + @Ind + ' ON dbo.' + @Tbl + ' REBUILD' + @DataComp; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Ind, @Action = 'Rebuild', @Text = @Txt; + DELETE @Indexes + WHERE IndId = @IndId; + END + INSERT INTO @ResourceTypes + SELECT CONVERT (SMALLINT, substring(name, charindex('_', name) + 1, 6)) AS ResourceTypeId + FROM sys.objects AS O + WHERE name LIKE @Tbl + '[_]%' + AND EXISTS (SELECT * + FROM sysindexes + WHERE id = O.object_id + AND indid IN (0, 1) + AND rows > 0); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '#ResourceTypes', @Action = 'Select Into', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @ResourceTypes); + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt; + SET @Txt = 'ALTER TABLE dbo.' + @TblInt + ' SWITCH TO dbo.' + @Tbl + ' PARTITION $partition.PartitionFunction_ResourceTypeId(' + CONVERT (VARCHAR, @ResourceTypeId) + ')'; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch in start', @Text = @Txt; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch in', @Text = @Txt; + IF EXISTS (SELECT * + FROM sysindexes + WHERE id = object_id(@TblInt) + AND rows > 0) + BEGIN + SET @Txt = @TblInt + ' is not empty after switch'; + RAISERROR (@Txt, 18, 127); + END + EXECUTE ('DROP TABLE dbo.' + @TblInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Drop'; + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsInAllTables +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsInAllTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId', @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SET @Tbl = (SELECT TOP 1 name + FROM @Tables + ORDER BY name); + EXECUTE dbo.SwitchPartitionsIn @Tbl = @Tbl; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'SwitchPartitionsIn', @Action = 'Execute', @Text = @Tbl; + DELETE @Tables + WHERE name = @Tbl; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsOut +@Tbl VARCHAR (100), @RebuildClustered BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsOut', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL') + ' ND=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @ResourceTypeId AS SMALLINT, @Rows AS BIGINT, @Txt AS VARCHAR (MAX), @TblInt AS VARCHAR (100), @IndId AS INT, @Ind AS VARCHAR (200), @Name AS VARCHAR (100), @checkName AS VARCHAR (200), @definition AS VARCHAR (200); +DECLARE @Indexes TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200), + IsDisabled BIT ); +DECLARE @IndexesRT TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200), + IsDisabled BIT ); +DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY, + partition_number_roundtrip INT , + partition_number INT , + row_count BIGINT ); +DECLARE @Names TABLE ( + name VARCHAR (100) PRIMARY KEY); +DECLARE @CheckConstraints TABLE ( + CheckName VARCHAR (200), + CheckDefinition VARCHAR (200)); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + IF @RebuildClustered IS NULL + RAISERROR ('@RebuildClustered IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT index_id, + name, + is_disabled + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (is_disabled = 0 + OR @RebuildClustered = 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + INSERT INTO @ResourceTypes + SELECT partition_number - 1 AS ResourceTypeId, + $PARTITION.PartitionFunction_ResourceTypeId (partition_number - 1) AS partition_number_roundtrip, + partition_number, + row_count + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@Tbl) + AND index_id = 1 + AND row_count > 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@ResourceTypes', @Action = 'Insert', @Rows = @@rowcount, @Text = 'For partition switch'; + IF EXISTS (SELECT * + FROM @ResourceTypes + WHERE partition_number_roundtrip <> partition_number) + RAISERROR ('Partition sanity check failed', 18, 127); + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SELECT TOP 1 @ResourceTypeId = ResourceTypeId, + @Rows = row_count + FROM @ResourceTypes + ORDER BY ResourceTypeId; + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + SET @Txt = 'Starting @ResourceTypeId=' + CONVERT (VARCHAR, @ResourceTypeId) + ' row_count=' + CONVERT (VARCHAR, @Rows); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Text = @Txt; + IF NOT EXISTS (SELECT * + FROM sysindexes + WHERE id = object_id(@TblInt) + AND rows > 0) + BEGIN + IF object_id(@TblInt) IS NOT NULL + BEGIN + EXECUTE ('DROP TABLE dbo.' + @TblInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Drop'; + END + EXECUTE ('SELECT * INTO dbo.' + @TblInt + ' FROM dbo.' + @Tbl + ' WHERE 1 = 2'); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Select Into', @Rows = @@rowcount; + DELETE @CheckConstraints; + INSERT INTO @CheckConstraints + SELECT name, + definition + FROM sys.check_constraints + WHERE parent_object_id = object_id(@Tbl); + WHILE EXISTS (SELECT * + FROM @CheckConstraints) + BEGIN + SELECT TOP 1 @checkName = CheckName, + @definition = CheckDefinition + FROM @CheckConstraints; + SET @Txt = 'ALTER TABLE ' + @TblInt + ' ADD CHECK ' + @definition; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'ALTER', @Text = @Txt; + DELETE @CheckConstraints + WHERE CheckName = @checkName; + END + DELETE @Names; + INSERT INTO @Names + SELECT name + FROM sys.columns + WHERE object_id = object_id(@Tbl) + AND is_sparse = 1; + WHILE EXISTS (SELECT * + FROM @Names) + BEGIN + SET @Name = (SELECT TOP 1 name + FROM @Names + ORDER BY name); + SET @Txt = (SELECT 'ALTER TABLE dbo.' + @TblInt + ' ALTER COLUMN ' + @Name + ' ' + T.name + '(' + CONVERT (VARCHAR, C.precision) + ',' + CONVERT (VARCHAR, C.scale) + ') SPARSE NULL' + FROM sys.types AS T + INNER JOIN + sys.columns AS C + ON C.system_type_id = T.system_type_id + WHERE C.object_id = object_id(@Tbl) + AND C.name = @Name); + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'ALTER', @Text = @Txt; + DELETE @Names + WHERE name = @Name; + END + END + INSERT INTO @IndexesRT + SELECT * + FROM @Indexes + WHERE IsDisabled = 0; + WHILE EXISTS (SELECT * + FROM @IndexesRT) + BEGIN + SELECT TOP 1 @IndId = IndId, + @Ind = name + FROM @IndexesRT + ORDER BY IndId; + IF NOT EXISTS (SELECT * + FROM sys.indexes + WHERE object_id = object_id(@TblInt) + AND name = @Ind) + BEGIN + EXECUTE dbo.GetIndexCommands @Tbl = @Tbl, @Ind = @Ind, @AddPartClause = 0, @IncludeClustered = 1, @Txt = @Txt OUTPUT; + SET @Txt = replace(@Txt, '[' + @Tbl + ']', @TblInt); + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Create Index', @Text = @Txt; + END + DELETE @IndexesRT + WHERE IndId = @IndId; + END + SET @Txt = 'ALTER TABLE dbo.' + @TblInt + ' ADD CHECK (ResourceTypeId >= ' + CONVERT (VARCHAR, @ResourceTypeId) + ' AND ResourceTypeId < ' + CONVERT (VARCHAR, @ResourceTypeId) + ' + 1)'; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Add check', @Text = @Txt; + SET @Txt = 'ALTER TABLE dbo.' + @Tbl + ' SWITCH PARTITION $partition.PartitionFunction_ResourceTypeId(' + CONVERT (VARCHAR, @ResourceTypeId) + ') TO dbo.' + @TblInt; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch out start', @Text = @Txt; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch out end', @Text = @Txt; + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsOutAllTables +@RebuildClustered BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsOutAllTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId ND=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = @RebuildClustered, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SET @Tbl = (SELECT TOP 1 name + FROM @Tables + ORDER BY name); + EXECUTE dbo.SwitchPartitionsOut @Tbl = @Tbl, @RebuildClustered = @RebuildClustered; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'SwitchPartitionsOut', @Action = 'Execute', @Text = @Tbl; + DELETE @Tables + WHERE name = @Tbl; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +GO +CREATE OR ALTER PROCEDURE dbo.UpdateEventAgentCheckpoint +@CheckpointId VARCHAR (64), @LastProcessedDateTime DATETIMEOFFSET (7)=NULL, @LastProcessedIdentifier VARCHAR (64)=NULL +AS +BEGIN + IF EXISTS (SELECT * + FROM dbo.EventAgentCheckpoint + WHERE CheckpointId = @CheckpointId) + UPDATE dbo.EventAgentCheckpoint + SET CheckpointId = @CheckpointId, + LastProcessedDateTime = @LastProcessedDateTime, + LastProcessedIdentifier = @LastProcessedIdentifier, + UpdatedOn = sysutcdatetime() + WHERE CheckpointId = @CheckpointId; + ELSE + INSERT INTO dbo.EventAgentCheckpoint (CheckpointId, LastProcessedDateTime, LastProcessedIdentifier, UpdatedOn) + VALUES (@CheckpointId, @LastProcessedDateTime, @LastProcessedIdentifier, sysutcdatetime()); +END + +GO +CREATE PROCEDURE dbo.UpdateReindexJob +@id VARCHAR (64), @status VARCHAR (10), @rawJobRecord VARCHAR (MAX), @jobVersion BINARY (8) +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +BEGIN TRANSACTION; +DECLARE @currentJobVersion AS BINARY (8); +SELECT @currentJobVersion = JobVersion +FROM dbo.ReindexJob WITH (UPDLOCK, HOLDLOCK) +WHERE Id = @id; +IF (@currentJobVersion IS NULL) + BEGIN + THROW 50404, 'Reindex job record not found', 1; + END +IF (@jobVersion <> @currentJobVersion) + BEGIN + THROW 50412, 'Precondition failed', 1; + END +DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); +UPDATE dbo.ReindexJob +SET Status = @status, + HeartbeatDateTime = @heartbeatDateTime, + RawJobRecord = @rawJobRecord +WHERE Id = @id; +SELECT @@DBTS; +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.UpdateResourceSearchParams +@FailedResources INT=0 OUTPUT, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParams dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) + FROM @Resources), 'Input=Empty'), @Rows AS INT; +BEGIN TRY + DECLARE @Ids TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL); + BEGIN TRANSACTION; + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash + FROM @Resources AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource AS B + WHERE EXISTS (SELECT * + FROM @Resources AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0; + SET @Rows = @@rowcount; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ResourceWriteClaim AS B + ON B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM dbo.ReferenceSearchParam AS B + WHERE EXISTS (SELECT * + FROM @Ids AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId); + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenText AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.StringSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.UriSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.NumberSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.QuantitySearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.DateTimeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ReferenceTokenCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenTokenCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenDateTimeCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenQuantityCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenStringCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenNumberNumberCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM @ResourceWriteClaims; + INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceId, + ReferenceResourceVersion + FROM @ReferenceSearchParams; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM @TokenSearchParams; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM @TokenTexts; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM @StringSearchParams; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM @UriSearchParams; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM @NumberSearchParams; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM @QuantitySearchParams; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM @DateTimeSearchParams; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM @TokenTokenCompositeSearchParams; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM @TokenQuantityCompositeSearchParams; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM @TokenStringCompositeSearchParams; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM @TokenNumberNumberCompositeSearchParams; + COMMIT TRANSACTION; + SET @FailedResources = (SELECT count(*) + FROM @Resources) - @Rows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.UpsertSearchParams +@searchParams dbo.SearchParamTableType_2 READONLY +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; +BEGIN TRANSACTION; +DECLARE @lastUpdated AS DATETIMEOFFSET (7) = SYSDATETIMEOFFSET(); +DECLARE @summaryOfChanges TABLE ( + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Action VARCHAR (20) NOT NULL); +MERGE INTO dbo.SearchParam WITH (TABLOCKX) + AS target +USING @searchParams AS source ON target.Uri = source.Uri +WHEN MATCHED THEN UPDATE +SET Status = source.Status, + LastUpdated = @lastUpdated, + IsPartiallySupported = source.IsPartiallySupported +WHEN NOT MATCHED BY TARGET THEN INSERT (Uri, Status, LastUpdated, IsPartiallySupported) VALUES (source.Uri, source.Status, @lastUpdated, source.IsPartiallySupported) +OUTPUT source.Uri, $ACTION INTO @summaryOfChanges; +SELECT SearchParamId, + SearchParam.Uri +FROM dbo.SearchParam AS searchParam + INNER JOIN + @summaryOfChanges AS upsertedSearchParam + ON searchParam.Uri = upsertedSearchParam.Uri +WHERE upsertedSearchParam.Action = 'INSERT'; +COMMIT TRANSACTION; + +GO +EXECUTE sp_rename 'ReferenceSearchParam', 'ReferenceSearchParamTbl'; + + +GO +CREATE OR ALTER VIEW dbo.ReferenceSearchParam +AS +SELECT A.ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + CASE WHEN A.ReferenceResourceId = '' THEN B.ResourceId ELSE A.ReferenceResourceId END AS ReferenceResourceId, + ReferenceResourceVersion +FROM dbo.ReferenceSearchParamTbl AS A + LEFT OUTER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ReferenceResourceTypeId + AND B.ResourceIdInt = A.ReferenceResourceIdInt; + + +GO +CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamIns + ON dbo.ReferenceSearchParam + INSTEAD OF INSERT + AS DECLARE @DummyTop AS BIGINT = 9223372036854775807; + BEGIN + INSERT INTO dbo.ReferenceSearchParamTbl (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT A.ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + B.ResourceIdInt, + ReferenceResourceVersion + FROM (SELECT TOP (@DummyTop) * + FROM Inserted) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ReferenceResourceTypeId + AND B.ResourceId = A.ReferenceResourceId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + END + + +GO +CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamUpd + ON dbo.ReferenceSearchParam + INSTEAD OF UPDATE + AS BEGIN + RAISERROR ('Generic updates are not supported via ReferenceSearchParam view', 18, 127); + END + + +GO +CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamDel + ON dbo.ReferenceSearchParam + INSTEAD OF DELETE + AS BEGIN + DELETE A + FROM dbo.ReferenceSearchParamTbl AS A + WHERE EXISTS (SELECT * + FROM Deleted AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId); + END + +GO +EXECUTE sp_rename 'Resource', 'ResourceTbl'; + + +GO +CREATE OR ALTER VIEW dbo.Resource +AS +SELECT A.ResourceTypeId, + ResourceSurrogateId, + CASE WHEN A.ResourceId = '' THEN B.ResourceId ELSE A.ResourceId END AS ResourceId, + Version, + IsHistory, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId, + OffsetInFile +FROM dbo.ResourceTbl AS A + LEFT OUTER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt; + + +GO +CREATE OR ALTER TRIGGER dbo.ResourceIns + ON dbo.Resource + INSTEAD OF INSERT + AS DECLARE @DummyTop AS BIGINT = 9223372036854775807; + BEGIN + INSERT INTO dbo.ResourceTbl (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsHistory, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile) + SELECT A.ResourceTypeId, + ResourceSurrogateId, + ResourceIdInt, + Version, + IsHistory, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId, + OffsetInFile + FROM (SELECT TOP (@DummyTop) * + FROM Inserted) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + END + + +GO +CREATE OR ALTER TRIGGER dbo.ResourceUpd + ON dbo.Resource + INSTEAD OF UPDATE + AS BEGIN + IF UPDATE (SearchParamHash) + AND NOT UPDATE (IsHistory) + BEGIN + UPDATE B + SET SearchParamHash = A.SearchParamHash + FROM Inserted AS A + INNER JOIN + dbo.ResourceTbl AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE A.IsHistory = 0; + RETURN; + END + IF NOT UPDATE (IsHistory) + RAISERROR ('Generic updates are not supported via Resource view', 18, 127); + UPDATE B + SET IsHistory = A.IsHistory + FROM Inserted AS A + INNER JOIN + dbo.ResourceTbl AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + END + + +GO +CREATE OR ALTER TRIGGER dbo.ResourceDel + ON dbo.Resource + INSTEAD OF DELETE + AS BEGIN + DELETE A + FROM dbo.ResourceTbl AS A + WHERE EXISTS (SELECT * + FROM Deleted AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId); + END + +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs index cb619b3a6a..e633808e9d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs @@ -92,5 +92,7 @@ public enum SchemaVersion V80 = 80, V81 = 81, V82 = 82, + V83 = 83, + V84 = 84, } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs index 37feaf47d6..b16e3037ba 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs @@ -7,8 +7,8 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema { public static class SchemaVersionConstants { - public const int Min = (int)SchemaVersion.V80; - public const int Max = (int)SchemaVersion.V82; + public const int Min = (int)SchemaVersion.V84; + public const int Max = (int)SchemaVersion.V84; public const int MinForUpgrade = (int)SchemaVersion.V80; // this is used for upgrade tests only public const int SearchParameterStatusSchemaVersion = (int)SchemaVersion.V6; public const int SupportForReferencesWithMissingTypeVersion = (int)SchemaVersion.V7; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/Sequences.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/Sequences.sql index ffa8769217..e8e0f7c909 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/Sequences.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/Sequences.sql @@ -13,3 +13,12 @@ CREATE SEQUENCE dbo.ResourceSurrogateIdUniquifierSequence CYCLE CACHE 1000000 GO +CREATE SEQUENCE dbo.ResourceIdIntMapSequence + AS int + START WITH 0 + INCREMENT BY 1 + MINVALUE 0 + MAXVALUE 79999 + CYCLE + CACHE 1000000 +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql index d10d1c47bd..4e8bc838ee 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql @@ -19,6 +19,6 @@ Go INSERT INTO dbo.SchemaVersion VALUES - (82, 'started') + (84, 'started') Go diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/AssignResourceIdInts.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/AssignResourceIdInts.sql new file mode 100644 index 0000000000..8beb517310 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/AssignResourceIdInts.sql @@ -0,0 +1,29 @@ +CREATE PROCEDURE dbo.AssignResourceIdInts @Count int, @FirstIdInt bigint OUT +AS +set nocount on +DECLARE @SP varchar(100) = 'AssignResourceIdInts' + ,@Mode varchar(200) = 'Cnt='+convert(varchar,@Count) + ,@st datetime = getUTCdate() + ,@FirstValueVar sql_variant + ,@LastValueVar sql_variant + ,@SequenceRangeFirstValue int + +BEGIN TRY + SET @FirstValueVar = NULL + WHILE @FirstValueVar IS NULL + BEGIN + EXECUTE sys.sp_sequence_get_range @sequence_name = 'dbo.ResourceIdIntMapSequence', @range_size = @Count, @range_first_value = @FirstValueVar OUT, @range_last_value = @LastValueVar OUT + SET @SequenceRangeFirstValue = convert(int,@FirstValueVar) + IF @SequenceRangeFirstValue > convert(int,@LastValueVar) + SET @FirstValueVar = NULL + END + + SET @FirstIdInt = datediff_big(millisecond,'0001-01-01',sysUTCdatetime()) * 80000 + @SequenceRangeFirstValue +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + THROW +END CATCH +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql index e5293388cd..0d38e37d1a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql @@ -22,6 +22,8 @@ BEGIN TRY END ,MatchedVersion = isnull(D.Version,0) ,MatchedRawResource = D.RawResource + ,MatchedTransactionId = D.TransactionId + ,MatchedOffsetInFile = D.OffsetInFile -- ResourceIndex allows to deal with more than one late arrival per resource FROM (SELECT TOP (@DummyTop) *, ResourceIndex = convert(int,row_number() OVER (PARTITION BY ResourceTypeId, ResourceId ORDER BY ResourceSurrogateId DESC)) FROM @ResourceDateKeys) A OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index b9eb179a76..1b48a6cfc2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -22,40 +22,49 @@ BEGIN TRY SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash + ,TransactionId + ,OffsetInFile FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) ELSE SELECT * FROM (SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash + ,TransactionId + ,OffsetInFile FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash + ,TransactionId + ,OffsetInFile FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' WHERE IsHistory = 0 ) A OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) @@ -63,14 +72,17 @@ BEGIN TRY SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash + ,TransactionId + ,OffsetInFile FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' WHERE IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql index e5e8a18c83..e149e1d617 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql @@ -34,6 +34,8 @@ BEGIN TRY ,IsRawResourceMetaSet ,SearchParamHash ,RequestMethod + ,TransactionId + ,OffsetInFile FROM (SELECT TOP (@DummyTop) * FROM @Keys) A JOIN dbo.Resource B ON ResourceTypeId = TypeId AND ResourceSurrogateId = SurrogateId WHERE IsHistory = 0 OR @IncludeHistory = 1 diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql index 4b8115c946..c18f8e5c9f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql @@ -42,14 +42,14 @@ BEGIN TRY OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) END - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, TransactionId, OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND (IsHistory = 0 OR @IncludeHistory = 1) AND (IsDeleted = 0 OR @IncludeDeleted = 1) UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, TransactionId, OffsetInFile FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql index 6b85ea2747..9dad047285 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql @@ -41,7 +41,7 @@ BEGIN TRY BEGIN -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM dbo.ReferenceSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index d6e4ca76ed..4c55f9128b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -33,6 +33,9 @@ DECLARE @st datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 ,@InitialTranCount int = @@trancount ,@IsRetry bit = 0 + ,@RT smallint + ,@NewIdsCount int + ,@FirstIdInt bigint DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') @@ -40,6 +43,136 @@ SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(var SET @AffectedRows = 0 BEGIN TRY + DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) + DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertIds AS TABLE (ResourceIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL) + DECLARE @InsertedIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ResourcesWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,IsDeleted bit NOT NULL + ,IsHistory bit NOT NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,RequestMethod varchar(10) NULL + ,SearchParamHash varchar(64) NULL + ,OffsetInFile int NULL + + PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) + ,UNIQUE (ResourceTypeId, ResourceIdInt, Version) + ) + DECLARE @ReferenceSearchParamsWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,ReferenceResourceVersion int NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) + ) + + INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL + INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds + +-- Prepare id map for reference search params Start --------------------------------------------------------------------------- + WHILE EXISTS (SELECT * FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) + + INSERT INTO @ExistingIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT @RT, ResourceIdInt, A.ResourceId + FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId + + DELETE FROM @InsertIds + + INSERT INTO @InsertIds + ( ResourceIndex, ResourceId ) + SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId + FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A + WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + DELETE FROM @RTs WHERE ResourceTypeId = @RT + END + + INSERT INTO @ReferenceSearchParamsWithIds + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), ReferenceResourceVersion + FROM @ReferenceSearchParams A + LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId +-- Prepare id map for reference search params End --------------------------------------------------------------------------- + + DELETE FROM @InputIds + DELETE FROM @RTs + DELETE FROM @InsertedIds + DELETE FROM @ExistingIds + +-- Prepare id map for resources Start --------------------------------------------------------------------------- + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @Resources GROUP BY ResourceTypeId, ResourceId + INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds + + WHILE EXISTS (SELECT * FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) + + INSERT INTO @ExistingIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT @RT, ResourceIdInt, A.ResourceId + FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId + + DELETE FROM @InsertIds + + INSERT INTO @InsertIds + ( ResourceIndex, ResourceId ) + SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId + FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A + WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + DELETE FROM @RTs WHERE ResourceTypeId = @RT + END + + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile + FROM @Resources A + LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId +-- Prepare id map for resources End --------------------------------------------------------------------------- + DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) DECLARE @ResourceInfos AS TABLE @@ -161,10 +294,10 @@ BEGIN TRY --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' END - INSERT INTO dbo.Resource - ( ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId ) - SELECT ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId - FROM @Resources + INSERT INTO dbo.ResourceTbl + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile ) + SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, OffsetInFile + FROM @ResourcesWithIds SET @AffectedRows += @@rowcount INSERT INTO dbo.ResourceWriteClaim @@ -173,10 +306,10 @@ BEGIN TRY FROM @ResourceWriteClaims SET @AffectedRows += @@rowcount - INSERT INTO dbo.ReferenceSearchParam - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) - SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion - FROM @ReferenceSearchParams + INSERT INTO dbo.ReferenceSearchParamTbl + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion + FROM @ReferenceSearchParamsWithIds SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenSearchParam @@ -268,12 +401,12 @@ BEGIN TRY OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount - INSERT INTO dbo.ReferenceSearchParam - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) - SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion - FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams) A + INSERT INTO dbo.ReferenceSearchParamTbl + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParamsWithIds) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) - AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParamTbl C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount @@ -411,7 +544,7 @@ BEGIN CATCH EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.Resource''%' + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.Resource%' THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; ELSE THROW diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql index 88f4c2bfdf..caabda7842 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql @@ -30,15 +30,16 @@ BEGIN TRY -- Update the search parameter hash value in the main resource table UPDATE B - SET SearchParamHash = A.SearchParamHash + SET SearchParamHash = (SELECT SearchParamHash FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids - FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - WHERE B.IsHistory = 0 + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 SET @Rows = @@rowcount -- First, delete all the search params of the resources to reindex. DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.ReferenceSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM dbo.ReferenceSearchParam B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index 42e498bb4c..45e794f558 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -1,35 +1,34 @@ CREATE TABLE dbo.ReferenceSearchParam ( - ResourceTypeId smallint NOT NULL, - ResourceSurrogateId bigint NOT NULL, - SearchParamId smallint NOT NULL, - BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL, - ReferenceResourceTypeId smallint NULL, - ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL, - ReferenceResourceVersion int NULL + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL CONSTRAINT DF_ReferenceSearchParam_ResourceIdInt DEFAULT 0 + ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT DF_ReferenceSearchParam_ResourceId DEFAULT '' + ,ReferenceResourceVersion int NULL + + ,CONSTRAINT CH_ReferenceSearchParam_ReferenceResourceIdInt_ReferenceResourceId CHECK (ReferenceResourceIdInt = 0 AND ReferenceResourceId <> '' OR ReferenceResourceIdInt <> 0 AND ReferenceResourceId = '') ) ALTER TABLE dbo.ReferenceSearchParam SET ( LOCK_ESCALATION = AUTO ) -CREATE CLUSTERED INDEX IXC_ReferenceSearchParam -ON dbo.ReferenceSearchParam -( - ResourceTypeId, - ResourceSurrogateId, - SearchParamId -) -WITH (DATA_COMPRESSION = PAGE) -ON PartitionScheme_ResourceTypeId(ResourceTypeId) +CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.ReferenceSearchParam (ResourceSurrogateId, SearchParamId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE UNIQUE INDEX IXU_ReferenceResourceId_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId ON dbo.ReferenceSearchParam +CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceId_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId ON dbo.ReferenceSearchParam ( - ReferenceResourceId + ReferenceResourceIdInt + ,ReferenceResourceId ,ReferenceResourceTypeId ,SearchParamId ,BaseUri ,ResourceSurrogateId ,ResourceTypeId ) - WITH (DATA_COMPRESSION = PAGE) - ON PartitionScheme_ResourceTypeId (ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql index e880a6b995..6786fbebb8 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql @@ -1,52 +1,41 @@ CREATE TABLE dbo.Resource ( - ResourceTypeId smallint NOT NULL, - ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL, - Version int NOT NULL, - IsHistory bit NOT NULL, - ResourceSurrogateId bigint NOT NULL, - IsDeleted bit NOT NULL, - RequestMethod varchar(10) NULL, - RawResource varbinary(max) NOT NULL, - IsRawResourceMetaSet bit NOT NULL DEFAULT 0, - SearchParamHash varchar(64) NULL, - TransactionId bigint NULL, -- used for main CRUD operation - HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state + ResourceTypeId smallint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT DF_Resource_ResourceId DEFAULT '' + ,ResourceIdInt bigint NOT NULL CONSTRAINT DF_Resource_ResourceIdInt DEFAULT 0 + ,Version int NOT NULL + ,IsHistory bit NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL DEFAULT 0 + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL -- used for main CRUD operation + ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state + ,OffsetInFile int NULL - CONSTRAINT PKC_Resource PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId(ResourceTypeId), - CONSTRAINT CH_Resource_RawResource_Length CHECK (RawResource > 0x0) + CONSTRAINT PKC_Resource_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId(ResourceTypeId) + ,CONSTRAINT CH_Resource_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) + ,CONSTRAINT CH_Resource_ResourceIdInt_ResourceId CHECK (ResourceIdInt = 0 AND ResourceId <> '' OR ResourceIdInt <> 0 AND ResourceId = '') ) ALTER TABLE dbo.Resource SET ( LOCK_ESCALATION = AUTO ) -CREATE INDEX IX_ResourceTypeId_TransactionId ON dbo.Resource (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE INDEX IX_ResourceTypeId_HistoryTransactionId ON dbo.Resource (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.Resource (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId_Version ON dbo.Resource -( - ResourceTypeId, - ResourceId, - Version -) -ON PartitionScheme_ResourceTypeId(ResourceTypeId) +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.Resource (HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId ON dbo.Resource -( - ResourceTypeId, - ResourceId -) -INCLUDE -- We want the query in UpsertResource, which is done with UPDLOCK AND HOLDLOCK, to not require a key lookup -( - Version, - IsDeleted -) -WHERE IsHistory = 0 -ON PartitionScheme_ResourceTypeId(ResourceTypeId) +CREATE UNIQUE INDEX IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId ON dbo.Resource (ResourceIdInt, ResourceId, Version, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId ON dbo.Resource -( - ResourceTypeId, - ResourceSurrogateId -) -WHERE IsHistory = 0 AND IsDeleted = 0 -ON PartitionScheme_ResourceTypeId(ResourceTypeId) +-- Remove when history is separated +CREATE UNIQUE INDEX IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0 ON dbo.Resource (ResourceIdInt, ResourceId, ResourceTypeId) + INCLUDE (Version, IsDeleted) WHERE IsHistory = 0 + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + +-- Remove when history is separated. Leaving old name for backward compatibility +CREATE UNIQUE INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId ON dbo.Resource (ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 AND IsDeleted = 0 + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql new file mode 100644 index 0000000000..9ca9dfe62e --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql @@ -0,0 +1,11 @@ +CREATE TABLE dbo.ResourceIdIntMap +( + ResourceTypeId smallint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + + CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +) + +ALTER TABLE dbo.ResourceIdIntMap SET ( LOCK_ESCALATION = AUTO ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql index d27e6dd3f0..d79569064e 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql @@ -10,10 +10,11 @@ CREATE TYPE dbo.ResourceList AS TABLE ,IsDeleted bit NOT NULL ,IsHistory bit NOT NULL ,KeepHistory bit NOT NULL - ,RawResource varbinary(max) NOT NULL + ,RawResource varbinary(max) NULL ,IsRawResourceMetaSet bit NOT NULL ,RequestMethod varchar(10) NULL ,SearchParamHash varchar(64) NULL + ,OffsetInFile int NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) ,UNIQUE (ResourceTypeId, ResourceId, Version) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql new file mode 100644 index 0000000000..b0fe6b6fd1 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql @@ -0,0 +1,54 @@ +EXECUTE sp_rename 'ReferenceSearchParam', 'ReferenceSearchParamTbl' +GO +CREATE OR ALTER VIEW dbo.ReferenceSearchParam +AS +SELECT A.ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,ReferenceResourceTypeId + ,ReferenceResourceId = CASE WHEN A.ReferenceResourceId = '' THEN B.ResourceId ELSE A.ReferenceResourceId END + ,ReferenceResourceVersion + FROM dbo.ReferenceSearchParamTbl A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt +GO +CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamIns ON dbo.ReferenceSearchParam INSTEAD OF INSERT +AS +DECLARE @DummyTop bigint = 9223372036854775807 +BEGIN + INSERT INTO dbo.ReferenceSearchParamTbl + ( + ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,ReferenceResourceTypeId + ,ReferenceResourceIdInt + ,ReferenceResourceVersion + ) + SELECT A.ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,ReferenceResourceTypeId + ,B.ResourceIdInt + ,ReferenceResourceVersion + FROM (SELECT TOP (@DummyTop) * FROM Inserted) A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) +END +GO +CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamUpd ON dbo.ReferenceSearchParam INSTEAD OF UPDATE +AS +BEGIN + RAISERROR('Generic updates are not supported via ReferenceSearchParam view',18,127) +END +GO +CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamDel ON dbo.ReferenceSearchParam INSTEAD OF DELETE +AS +BEGIN + DELETE FROM A + FROM dbo.ReferenceSearchParamTbl A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql new file mode 100644 index 0000000000..e25d57bcf1 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -0,0 +1,89 @@ +EXECUTE sp_rename 'Resource', 'ResourceTbl' +GO +CREATE OR ALTER VIEW dbo.Resource +AS +SELECT A.ResourceTypeId + ,ResourceSurrogateId + ,ResourceId = CASE WHEN A.ResourceId = '' THEN B.ResourceId ELSE A.ResourceId END + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,OffsetInFile + FROM dbo.ResourceTbl A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt +GO +CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT +AS +DECLARE @DummyTop bigint = 9223372036854775807 +BEGIN + INSERT INTO dbo.ResourceTbl + ( + ResourceTypeId + ,ResourceSurrogateId + ,ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,OffsetInFile + ) + SELECT A.ResourceTypeId + ,ResourceSurrogateId + ,ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,OffsetInFile + FROM (SELECT TOP (@DummyTop) * FROM Inserted) A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) +END +GO +CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE +AS +BEGIN + IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) + BEGIN + UPDATE B + SET SearchParamHash = A.SearchParamHash + FROM Inserted A + JOIN dbo.ResourceTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE A.IsHistory = 0 + + RETURN + END + + IF NOT UPDATE(IsHistory) + RAISERROR('Generic updates are not supported via Resource view',18,127) + + UPDATE B + SET IsHistory = A.IsHistory + FROM Inserted A + JOIN dbo.ResourceTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId +END +GO +CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE +AS +BEGIN + DELETE FROM A + FROM dbo.ResourceTbl A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index e229ae7239..4c8b399307 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -208,6 +208,9 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions StringBuilder.Append(VLatest.Resource.RawResource, resourceTableAlias); + StringBuilder.Append(", ").Append(VLatest.Resource.TransactionId, resourceTableAlias); + StringBuilder.Append(", ").Append(VLatest.Resource.OffsetInFile, resourceTableAlias); + if (IsSortValueNeeded(context)) { StringBuilder.Append(", ").Append(TableExpressionName(_tableExpressionCounter)).Append(".SortValue"); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 50201cb4ad..192779fc87 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -8,6 +8,7 @@ using System.Collections.Concurrent; using System.Collections.Generic; using System.Data; +using System.Data.SqlTypes; using System.Diagnostics; using System.Globalization; using System.IO; @@ -437,7 +438,9 @@ await _sqlRetryService.ExecuteSql( out bool isPartialEntry, out bool isRawResourceMetaSet, out string searchParameterHash, - out byte[] rawResourceBytes, + out SqlBytes rawResourceSqlBytes, + out long? transactionId, + out int? offsetInFile, out bool isInvisible); if (isInvisible) @@ -462,8 +465,7 @@ await _sqlRetryService.ExecuteSql( { rawResource = new Lazy(() => { - using var rawResourceStream = new MemoryStream(rawResourceBytes); - var decompressedResource = _compressedRawResourceConverter.ReadCompressedRawResource(rawResourceStream); + var decompressedResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(resourceSurrogateId), resourceSurrogateId, nameof(resourceTypeId), resourceTypeId, decompressedResource.Length); @@ -649,7 +651,9 @@ await _sqlRetryService.ExecuteSql( out bool isPartialEntry, out bool isRawResourceMetaSet, out string searchParameterHash, - out byte[] rawResourceBytes, + out SqlBytes rawResourceSqlBytes, + out long? transactionId, + out int? offsetInFile, out bool isInvisible); if (isInvisible) @@ -663,8 +667,7 @@ await _sqlRetryService.ExecuteSql( continue; } - using var rawResourceStream = new MemoryStream(rawResourceBytes); - var rawResource = _compressedRawResourceConverter.ReadCompressedRawResource(rawResourceStream); + var rawResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); if (string.IsNullOrEmpty(rawResource)) { @@ -836,7 +839,9 @@ private void ReadWrapper( out bool isPartialEntry, out bool isRawResourceMetaSet, out string searchParameterHash, - out byte[] rawResourceBytes, + out SqlBytes rawResourceSqlBytes, + out long? transactionId, + out int? offsetInFile, out bool isInvisible) { resourceTypeId = reader.Read(VLatest.Resource.ResourceTypeId, 0); @@ -849,8 +854,18 @@ private void ReadWrapper( isPartialEntry = reader.Read(_isPartial, 7); isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 8); searchParameterHash = reader.Read(VLatest.Resource.SearchParamHash, 9); - rawResourceBytes = reader.GetSqlBytes(10).Value; - isInvisible = rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF; + rawResourceSqlBytes = reader.GetSqlBytes(10); + transactionId = reader.Read(VLatest.Resource.TransactionId, 11); + offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, 12); + isInvisible = false; + if (rawResourceSqlBytes != null) + { + var rawResourceBytes = rawResourceSqlBytes.Value; + if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) + { + isInvisible = true; + } + } } [Conditional("DEBUG")] diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/ISqlRetryService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/ISqlRetryService.cs index ab00060ffd..31cf599090 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/ISqlRetryService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/ISqlRetryService.cs @@ -14,6 +14,8 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Storage { public interface ISqlRetryService { + string Database { get; } + Task TryLogEvent(string process, string status, string text, DateTime? startDate, CancellationToken cancellationToken); Task ExecuteSql(Func action, ILogger logger, CancellationToken cancellationToken, bool isReadOnly = false); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs index dbcf22c287..b96f3406ac 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs @@ -72,6 +72,7 @@ private readonly HashSet _transientErrors private static ReplicaHandler _replicaHandler; private static object _initLocker = new object(); private static EventLogHandler _eventLogHandler; + private readonly string _database; /// /// Constructor that initializes this implementation of the ISqlRetryService interface. This class @@ -94,6 +95,12 @@ public SqlRetryService( _commandTimeout = (int)EnsureArg.IsNotNull(sqlServerDataStoreConfiguration?.Value, nameof(sqlServerDataStoreConfiguration)).CommandTimeout.TotalSeconds; _sqlConnectionBuilder = sqlConnectionBuilder; + _database = sqlConnectionBuilder.DefaultDatabase; + EnsureArg.IsNotNull(_database, "DefaultDatabase"); + if (_database == "master") + { + throw new ArgumentException("default database cannot be master"); + } if (sqlRetryServiceOptions.Value.RemoveTransientErrors != null) { @@ -131,6 +138,8 @@ private SqlRetryService(ISqlConnectionBuilder sqlConnectionBuilder) /// public delegate bool IsExceptionRetriable(Exception ex); + public string Database => _database; + /// /// Simplified class generator. /// diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlSecondaryStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlSecondaryStore.cs new file mode 100644 index 0000000000..3fd090a320 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlSecondaryStore.cs @@ -0,0 +1,113 @@ +// ------------------------------------------------------------------------------------------------- +// Copyright (c) Microsoft Corporation. All rights reserved. +// Licensed under the MIT License (MIT). See LICENSE in the repo root for license information. +// ------------------------------------------------------------------------------------------------- + +using System; +using System.Threading; +using Azure.Identity; +using Azure.Storage.Blobs; +using EnsureThat; +using Microsoft.Data.SqlClient; +using Microsoft.Extensions.Logging; + +namespace Microsoft.Health.Fhir.SqlServer.Features.Storage +{ + internal class SqlSecondaryStore + { + private static readonly object _parameterLocker = new object(); + private static string _adlsContainer; + private static string _adlsConnectionString; + private static string _adlsAccountName; + private static string _adlsAccountKey; + private static Uri _adlsAccountUri; + private static string _adlsAccountManagedIdentityClientId; + private static BlobContainerClient _adlsClient; + private static bool _adlsIsSet; + + public SqlSecondaryStore(ISqlRetryService sqlRetryService, ILogger logger) + { + EnsureArg.IsNotNull(sqlRetryService, nameof(sqlRetryService)); + + if (!_adlsIsSet) + { + lock (_parameterLocker) + { + if (!_adlsIsSet) + { + _adlsAccountName = GetStorageParameter(sqlRetryService, logger, "MergeResources.AdlsAccountName"); + _adlsConnectionString = GetStorageParameter(sqlRetryService, logger, "MergeResources.AdlsConnectionString"); + if (_adlsAccountName != null) + { + _adlsAccountKey = GetStorageParameter(sqlRetryService, logger, "MergeResources.AdlsAccountKey"); + _adlsConnectionString = $"DefaultEndpointsProtocol=https;AccountName={_adlsAccountName};AccountKey={_adlsAccountKey};EndpointSuffix=core.windows.net"; + } + + var db = sqlRetryService.Database.Length < 50 ? sqlRetryService.Database : sqlRetryService.Database.Substring(0, 50); + _adlsContainer = $"fhir-adls-{db.Replace("_", "-", StringComparison.InvariantCultureIgnoreCase).ToLowerInvariant()}"; + + var uriStr = GetStorageParameter(sqlRetryService, logger, "MergeResources.AdlsAccountUri"); + if (uriStr != null) + { + _adlsAccountUri = new Uri(uriStr); + _adlsAccountManagedIdentityClientId = GetStorageParameter(sqlRetryService, logger, "MergeResources.AdlsAccountManagedIdentityClientId"); + } + + if (_adlsConnectionString != null || _adlsAccountUri != null) + { + _adlsClient = GetAdlsContainer(); + } + + _adlsIsSet = true; + } + } + } + } + + public static BlobContainerClient AdlsClient => _adlsIsSet ? _adlsClient : throw new ArgumentOutOfRangeException(); + + public static string AdlsContainer => _adlsIsSet ? _adlsContainer : throw new ArgumentOutOfRangeException(); + + public static string AdlsAccountName => _adlsIsSet ? _adlsAccountName : throw new ArgumentOutOfRangeException(); + + public static string AdlsAccountKey => _adlsIsSet ? _adlsAccountKey : throw new ArgumentOutOfRangeException(); + + private static string GetStorageParameter(ISqlRetryService sqlRetryService, ILogger logger, string parameterId) + { + lock (_parameterLocker) + { + try + { + using var cmd = new SqlCommand(); + cmd.CommandText = "IF object_id('dbo.Parameters') IS NOT NULL SELECT Char FROM dbo.Parameters WHERE Id = @Id"; + cmd.Parameters.AddWithValue("@Id", parameterId); + var value = cmd.ExecuteScalarAsync(sqlRetryService, logger, CancellationToken.None).Result; + return value == null ? null : (string)value; + } + catch (Exception) + { + return null; + } + } + } + + private static BlobContainerClient GetAdlsContainer() // creates if does not exist + { + var blobContainerClient = _adlsAccountUri != null && _adlsAccountManagedIdentityClientId != null + ? new BlobContainerClient(new Uri(_adlsAccountUri, _adlsContainer), new ManagedIdentityCredential(_adlsAccountManagedIdentityClientId)) + : _adlsAccountUri != null + ? new BlobContainerClient(new Uri(_adlsAccountUri, _adlsContainer), new InteractiveBrowserCredential()) + : new BlobServiceClient(_adlsConnectionString).GetBlobContainerClient(_adlsContainer); + + if (!blobContainerClient.Exists()) + { + lock (_parameterLocker) + { + blobContainerClient.CreateIfNotExists(); + } + } + + return blobContainerClient; + } + } +} diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index d4ab819035..bbed8886e4 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -6,11 +6,15 @@ using System; using System.Collections.Generic; using System.Data; +using System.Diagnostics; using System.Globalization; +using System.IO; using System.Linq; using System.Security.Cryptography; +using System.Text; using System.Threading; using System.Threading.Tasks; +using Azure.Storage.Blobs.Specialized; using EnsureThat; using Hl7.FhirPath.Sprache; using Microsoft.Data.SqlClient; @@ -117,12 +121,69 @@ public SqlServerFhirDataStore( _rawResourceDeduping ??= new ProcessingFlag("MergeResources.RawResourceDeduping.IsEnabled", true, _logger); } } + + _ = new SqlSecondaryStore(_sqlRetryService, _logger); } internal SqlStoreClient StoreClient => _sqlStoreClient; internal static TimeSpan MergeResourcesTransactionHeartbeatPeriod => TimeSpan.FromSeconds(10); + private async Task PutRawResourcesIntoAdls(IReadOnlyList resources, long transactionId, CancellationToken cancellationToken) + { + var start = DateTime.UtcNow; + var sw = Stopwatch.StartNew(); + var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); + var blobName = GetBlobNameForRaw(transactionId); + retry: + try + { + using var stream = await SqlSecondaryStore.AdlsClient.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); + using var writer = new StreamWriter(stream); + var offset = 0; + foreach (var resource in resources) + { + resource.OffsetInFile = offset; + var line = resource.ResourceWrapper.RawResource.Data; + offset += Encoding.UTF8.GetByteCount(line) + eol; + await writer.WriteLineAsync(line); + } + + #pragma warning disable CA2016 + await writer.FlushAsync(); + } + catch (Exception e) + { + await StoreClient.TryLogEvent("PutRawResourcesIntoAdls", "Error", e.ToString(), start, cancellationToken); + if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) + { + await Task.Delay(1000, cancellationToken); + goto retry; + } + + throw; + } + + var mcsec = (long)Math.Round(sw.Elapsed.TotalMilliseconds * 1000, 0); + await StoreClient.TryLogEvent("PutRawResourcesToAdls", "Warn", $"mcsec={mcsec} Resources={resources.Count}", start, cancellationToken); + } + + internal static string GetBlobNameForRaw(long transactionId) + { + return $"hash-{GetPermanentHashCode(transactionId)}/transaction-{transactionId}.ndjson"; + } + + private static string GetPermanentHashCode(long tr) + { + var hashCode = 0; + foreach (var c in tr.ToString()) // Don't convert to LINQ. This is 10% faster. + { + hashCode = unchecked((hashCode * 251) + c); + } + + return (Math.Abs(hashCode) % 512).ToString().PadLeft(3, '0'); + } + public async Task> MergeAsync(IReadOnlyList resources, CancellationToken cancellationToken) { return await MergeAsync(resources, MergeOptions.Default, cancellationToken); @@ -415,7 +476,8 @@ internal async Task> ImportResourcesAsync(IReadOnlyList.AdlsClient != null) + { + await PutRawResourcesIntoAdls(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource + } + new ResourceListTableValuedParameterDefinition("@Resources").AddParameter(cmd.Parameters, new ResourceListRowGenerator(_model, _compressedRawResourceConverter).GenerateRows(mergeWrappers)); new ResourceWriteClaimListTableValuedParameterDefinition("@ResourceWriteClaims").AddParameter(cmd.Parameters, new ResourceWriteClaimListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); new ReferenceSearchParamListTableValuedParameterDefinition("@ReferenceSearchParams").AddParameter(cmd.Parameters, new ReferenceSearchParamListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirModel.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirModel.cs index 005e664053..8e73a060b7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirModel.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirModel.cs @@ -403,21 +403,9 @@ FROM dbo.SearchParam INNER JOIN @searchParamStatuses as sps SqlDbType = SqlDbType.Structured, Value = collection, Direction = ParameterDirection.Input, - TypeName = "dbo.SearchParamTableType_1", + TypeName = "dbo.SearchParamTableType_2", }; - if (_schemaInformation.Current >= (int)SchemaVersion.V52) - { - tableValuedParameter = new SqlParameter - { - ParameterName = "searchParamStatuses", - SqlDbType = SqlDbType.Structured, - Value = collection, - Direction = ParameterDirection.Input, - TypeName = "dbo.SearchParamTableType_2", - }; - } - sqlCommandWrapper.Parameters.Add(tableValuedParameter); sqlCommandWrapper.Parameters.Add(new SqlParameter("@RowsAffected", SqlDbType.Int) { Direction = ParameterDirection.Output }); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 309656f327..9f747e0979 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -6,17 +6,21 @@ using System; using System.Collections.Generic; using System.Data; +using System.Data.SqlTypes; using System.Globalization; using System.IO; using System.Linq; using System.Threading; using System.Threading.Tasks; +using Azure.Storage.Blobs; using EnsureThat; using Microsoft.Data.SqlClient; using Microsoft.Extensions.Logging; +using Microsoft.Health.Core.Features.Context; using Microsoft.Health.Fhir.Core.Features.Persistence; using Microsoft.Health.Fhir.Core.Models; using Microsoft.Health.Fhir.SqlServer.Features.Schema.Model; +using Microsoft.Health.Fhir.SqlServer.Features.Search; using Microsoft.Health.SqlServer.Features.Storage; using Task = System.Threading.Tasks.Task; @@ -30,7 +34,7 @@ internal class SqlStoreClient { private readonly ISqlRetryService _sqlRetryService; private readonly ILogger _logger; - private const string _invisibleResource = " "; + internal const string InvisibleResource = " "; public SqlStoreClient(ISqlRetryService sqlRetryService, ILogger logger) { @@ -74,7 +78,7 @@ public async Task> GetAsync(IReadOnlyList { return ReadResourceWrapper(reader, false, decompress, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != _invisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, false, decompress, SqlSecondaryStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); } catch (Exception e) { @@ -91,6 +95,17 @@ public async Task> GetAsync(IReadOnlyList GetRawResourceFromAdls(long transactionId, int offsetInFile) + { + return new Lazy(() => + { + var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(transactionId); + using var reader = new StreamReader(SqlSecondaryStore.AdlsClient.GetBlobClient(blobName).OpenRead(offsetInFile)); + var line = reader.ReadLine(); + return line; + }); + } + public async Task> GetResourceVersionsAsync(IReadOnlyList keys, Func decompress, CancellationToken cancellationToken) { if (keys == null || keys.Count == 0) @@ -112,10 +127,13 @@ public async Task> GetAsync(IReadOnlyList 4 && version == 0) + if (version == 0) // there is a match { matchedVersion = reader.Read(table.Version, 4).ToString(); - matchedRawResource = new RawResource(ReadRawResource(reader, decompress, 5), FhirResourceFormat.Json, true); + var bytes = reader.GetSqlBytes(5); + var matchedTransactionId = reader.Read(table.TransactionId, 6); + var matchedOffsetInFile = reader.Read(table.OffsetInFile, 7); + matchedRawResource = new RawResource(ReadRawResource(bytes, decompress, matchedTransactionId, matchedOffsetInFile), FhirResourceFormat.Json, true); } return (new ResourceDateKey(resourceTypeId, resourceId, resourceSurrogateId, version.ToString(CultureInfo.InvariantCulture)), (matchedVersion, matchedRawResource)); @@ -125,21 +143,22 @@ public async Task> GetAsync(IReadOnlyList ReadRawResource(SqlDataReader reader, Func decompress, int index) + internal static string ReadRawResource(SqlBytes bytes, Func decompress, long? transactionId, int? offsetInFile) { - var rawResourceBytes = reader.GetSqlBytes(index).Value; - Lazy rawResource; - if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) // invisible resource + var rawResourceBytes = bytes.IsNull ? null : bytes.Value; + string rawResource; + if (rawResourceBytes == null && offsetInFile.HasValue) // raw in adls { - rawResource = new Lazy(_invisibleResource); + rawResource = GetRawResourceFromAdls(transactionId.Value, offsetInFile.Value).Value; + } + else if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) // invisible resource + { + rawResource = InvisibleResource; } else { - rawResource = new Lazy(() => - { - using var rawResourceStream = new MemoryStream(rawResourceBytes); - return decompress(rawResourceStream); - }); + using var rawResourceStream = new MemoryStream(rawResourceBytes); + rawResource = decompress(rawResourceStream); } return rawResource; @@ -150,10 +169,10 @@ internal async Task> GetResourcesByTransactionIdA using var cmd = new SqlCommand() { CommandText = "dbo.GetResourcesByTransactionId", CommandType = CommandType.StoredProcedure, CommandTimeout = 600 }; cmd.Parameters.AddWithValue("@TransactionId", transactionId); //// ignore invisible resources - return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != _invisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlSecondaryStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); } - private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func decompress, Func getResourceTypeName) + private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func decompress, BlobContainerClient adlsClient, Func getResourceTypeName) { var resourceTypeId = reader.Read(VLatest.Resource.ResourceTypeId, 0); var resourceId = reader.Read(VLatest.Resource.ResourceId, 1); @@ -161,7 +180,10 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re var version = reader.Read(VLatest.Resource.Version, 3); var isDeleted = reader.Read(VLatest.Resource.IsDeleted, 4); var isHistory = reader.Read(VLatest.Resource.IsHistory, 5); - var rawResource = ReadRawResource(reader, decompress, 6); + var bytes = reader.GetSqlBytes(6); + var transactionId = reader.Read(VLatest.Resource.TransactionId, readRequestMethod ? 10 : 9); + var offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10); + var rawResource = ReadRawResource(bytes, decompress, transactionId.Value, offsetInFile); var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); var searchParamHash = reader.Read(VLatest.Resource.SearchParamHash, 8); var requestMethod = readRequestMethod ? reader.Read(VLatest.Resource.RequestMethod, 9) : null; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs index 2984d5bdd3..40615a2f6a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs @@ -30,5 +30,10 @@ internal MergeResourceWrapper(ResourceWrapper resourceWrapper, bool keepHistory, /// Flag indicating whether version in resource wrapper == (existing version in the database + 1) /// public bool HasVersionToCompare { get; internal set; } + + /// + /// Reasource record offset in adls file + /// + public int? OffsetInFile { get; internal set; } } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs index b4079fb525..4a97b5f63f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs @@ -34,7 +34,7 @@ public IEnumerable GenerateRows(IReadOnlyList - 82 + 84 Features\Schema\Migrations\$(LatestSchemaVersion).sql @@ -43,6 +43,7 @@ + diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs index 8187afa22a..b9e25960e8 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs @@ -79,10 +79,10 @@ public async Task RetriesOnConflict(int requestedExceptions) { await _fixture.SqlHelper.ExecuteSqlCmd("TRUNCATE TABLE EventLog"); await _fixture.SqlHelper.ExecuteSqlCmd(@$" -CREATE TRIGGER Resource_Trigger ON Resource FOR INSERT +CREATE TRIGGER Resource_Trigger ON ResourceTbl FOR INSERT AS IF (SELECT count(*) FROM EventLog WHERE Process = 'MergeResources' AND Status = 'Error') < {requestedExceptions} - INSERT INTO Resource SELECT * FROM inserted -- this will cause dup key exception which is treated as a conflict + INSERT INTO ResourceTbl SELECT * FROM inserted -- this will cause dup key exception which is treated as a conflict "); var patient = (Patient)Samples.GetJsonSample("Patient").ToPoco(); @@ -118,6 +118,7 @@ INSERT INTO Resource SELECT * FROM inserted -- this will cause dup key exception public async Task TimeTravel() { await _fixture.SqlHelper.ExecuteSqlCmd("DELETE FROM dbo.Resource"); // remove all data + await _fixture.SqlHelper.ExecuteSqlCmd("DELETE FROM dbo.ResourceIdIntMap"); // remove all data // add resource var type = "Patient"; @@ -196,15 +197,15 @@ public async Task TimeTravel() private async Task UpdateResource(Patient patient) { var oldId = patient.Id; - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET IsHistory = 1 WHERE ResourceId = '{oldId}' AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.ResourceTbl SET IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}') AND Version = 1"); var newId = Guid.NewGuid().ToString(); patient.Id = newId; await Mediator.UpsertResourceAsync(patient.ToResourceElement()); // there is no control to keep history, so insert as new and update to old - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET ResourceId = '{oldId}', Version = 2, IsHistory = 1 WHERE ResourceId = '{newId}' AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.ResourceTbl SET ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}'), Version = 2, IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1"); newId = Guid.NewGuid().ToString(); patient.Id = newId; await Mediator.UpsertResourceAsync(patient.ToResourceElement()); // there is no control to keep history, so insert as new and update to old - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET ResourceId = '{oldId}', Version = 3 WHERE ResourceId = '{newId}' AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.ResourceTbl SET ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}'), Version = 3 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1"); } [Fact] diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs index db7f5acc0b..bd6914d314 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs @@ -67,7 +67,9 @@ public SqlServerFhirStorageTestHelper( public async Task CreateAndInitializeDatabase(string databaseName, int maximumSupportedSchemaVersion, bool forceIncrementalSchemaUpgrade, SchemaInitializer schemaInitializer = null, CancellationToken cancellationToken = default) { - string testConnectionString = new SqlConnectionStringBuilder(_initialConnectionString) { InitialCatalog = databaseName }.ToString(); + var builder = new SqlConnectionStringBuilder(_initialConnectionString) { InitialCatalog = databaseName }; + var isLocal = builder.DataSource.Contains("local", StringComparison.OrdinalIgnoreCase); + var testConnectionString = builder.ToString(); await _dbSetupRetryPolicy.ExecuteAsync( async () => @@ -102,21 +104,39 @@ IF NOT EXISTS (SELECT * FROM sys.databases WHERE name = '{databaseName}') await _dbSetupRetryPolicy.ExecuteAsync( async () => { - await using SqlConnection connection = await _sqlConnectionBuilder.GetSqlConnectionAsync(databaseName, null, cancellationToken); - await connection.OpenAsync(cancellationToken); - await using SqlCommand sqlCommand = connection.CreateCommand(); - sqlCommand.CommandText = "SELECT 1"; - await sqlCommand.ExecuteScalarAsync(cancellationToken); - await connection.CloseAsync(); + using var conn = await _sqlConnectionBuilder.GetSqlConnectionAsync(databaseName, null, cancellationToken); + using var cmd = new SqlCommand("IF object_id('sp_changedbowner') IS NOT NULL EXECUTE sp_changedbowner 'sa'", conn); + await conn.OpenAsync(cancellationToken); + cmd.ExecuteNonQuery(); }); schemaInitializer ??= CreateSchemaInitializer(testConnectionString, maximumSupportedSchemaVersion); await _dbSetupRetryPolicy.ExecuteAsync(async () => { await schemaInitializer.InitializeAsync(forceIncrementalSchemaUpgrade, cancellationToken); }); await InitWatchdogsParameters(databaseName); await EnableDatabaseLogging(databaseName); + if (isLocal) + { + await EnableRawResourcesInAdls(databaseName); + } + await _sqlServerFhirModel.Initialize(maximumSupportedSchemaVersion, cancellationToken); } + public async Task EnableRawResourcesInAdls(string databaseName) + { + await _dbSetupRetryPolicy.ExecuteAsync(async () => + { + await using SqlConnection connection = await _sqlConnectionBuilder.GetSqlConnectionAsync(databaseName, cancellationToken: CancellationToken.None); + await connection.OpenAsync(CancellationToken.None); + await using SqlCommand sqlCommand = connection.CreateCommand(); + sqlCommand.CommandText = @" +INSERT INTO Parameters (Id,Char) SELECT 'MergeResources.AdlsConnectionString','UseDevelopmentStorage=true' + "; + await sqlCommand.ExecuteNonQueryAsync(CancellationToken.None); + await connection.CloseAsync(); + }); + } + public async Task EnableDatabaseLogging(string databaseName) { await _dbSetupRetryPolicy.ExecuteAsync(async () => diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs index 1c258a3749..0f558cad44 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs @@ -150,7 +150,7 @@ WHILE @i < 10000 public async Task RollTransactionForward() { ExecuteSql("TRUNCATE TABLE dbo.Transactions"); - ExecuteSql("TRUNCATE TABLE dbo.Resource"); + ExecuteSql("DELETE FROM dbo.Resource"); ExecuteSql("TRUNCATE TABLE dbo.NumberSearchParam"); using var cts = new CancellationTokenSource(); @@ -186,7 +186,7 @@ FOR INSERT Assert.Equal("Test", e.Message); } - Assert.Equal(1, GetCount("Resource")); // resource inserted + Assert.Equal(1, GetCount("ResourceTbl")); // resource inserted Assert.Equal(0, GetCount("NumberSearchParam")); // number is not inserted ExecuteSql("DROP TRIGGER dbo.tmp_NumberSearchParam"); From 5aca029212bba2ffce63d4162390bc98259ff3d8 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 2 Oct 2024 10:17:54 -0700 Subject: [PATCH 002/111] perf tweeks --- .../Schema/Sql/Sprocs/GetResourceVersions.sql | 13 ++++--- .../Schema/Sql/Sprocs/GetResources.sql | 31 +++++++-------- .../Schema/Sql/Sprocs/MergeResources.sql | 39 ++++++++++++++++--- 3 files changed, 57 insertions(+), 26 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql index 0d38e37d1a..d93e343ae2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql @@ -25,11 +25,14 @@ BEGIN TRY ,MatchedTransactionId = D.TransactionId ,MatchedOffsetInFile = D.OffsetInFile -- ResourceIndex allows to deal with more than one late arrival per resource - FROM (SELECT TOP (@DummyTop) *, ResourceIndex = convert(int,row_number() OVER (PARTITION BY ResourceTypeId, ResourceId ORDER BY ResourceSurrogateId DESC)) FROM @ResourceDateKeys) A - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version < 0 ORDER BY B.Version) M -- minus - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date + FROM (SELECT TOP (@DummyTop) A.*, M.ResourceIdInt, ResourceIndex = convert(int,row_number() OVER (PARTITION BY A.ResourceTypeId, A.ResourceId ORDER BY ResourceSurrogateId DESC)) + FROM @ResourceDateKeys A + LEFT OUTER JOIN dbo.ResourceIdIntMap M WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON M.ResourceTypeId = A.ResourceTypeId AND M.ResourceId = A.ResourceId + ) A + OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower + OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper + OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version < 0 ORDER BY B.Version) M -- minus + OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index 1b48a6cfc2..26552e59fe 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -6,7 +6,6 @@ set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = 'GetResources' ,@InputRows int - ,@DummyTop bigint = 9223372036854775807 ,@NotNullVersionExists bit ,@NullVersionExists bit ,@MinRT smallint @@ -30,10 +29,10 @@ BEGIN TRY ,SearchParamHash ,TransactionId ,OffsetInFile - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version + OPTION (MAXDOP 1) ELSE SELECT * FROM (SELECT B.ResourceTypeId @@ -47,9 +46,9 @@ BEGIN TRY ,SearchParamHash ,TransactionId ,OffsetInFile - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A - JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId @@ -62,12 +61,12 @@ BEGIN TRY ,SearchParamHash ,TransactionId ,OffsetInFile - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A - JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' WHERE IsHistory = 0 ) A - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + OPTION (MAXDOP 1) ELSE SELECT B.ResourceTypeId ,B.ResourceId @@ -80,11 +79,11 @@ BEGIN TRY ,SearchParamHash ,TransactionId ,OffsetInFile - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' WHERE IsHistory = 0 - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount END TRY diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 4c55f9128b..7158f22ec3 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -54,8 +54,10 @@ BEGIN TRY ,ResourceSurrogateId bigint NOT NULL ,ResourceIdInt bigint NOT NULL ,Version int NOT NULL + ,HasVersionToCompare bit NOT NULL -- in case of multiple versions per resource indicates that row contains (existing version + 1) value ,IsDeleted bit NOT NULL ,IsHistory bit NOT NULL + ,KeepHistory bit NOT NULL ,RawResource varbinary(max) NULL ,IsRawResourceMetaSet bit NOT NULL ,RequestMethod varchar(10) NULL @@ -166,12 +168,39 @@ BEGIN TRY END INSERT INTO @ResourcesWithIds - ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile ) - SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile + ( ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile FROM @Resources A LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Action='Insert',@Target='@ResourcesWithIds',@Rows=@@rowcount,@Start=@st + -- Prepare id map for resources End --------------------------------------------------------------------------- +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' + BEGIN + DELETE FROM @ResourcesWithIds + DELETE FROM @ReferenceSearchParamsWithIds + DELETE FROM @InputIds + DELETE FROM @RTs + DELETE FROM @InsertedIds + DELETE FROM @ExistingIds + + GOTO RetryResourceIdIntMapInsert + END + ELSE + THROW +END CATCH + +--EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Text='ResourceIdIntMap populated' + +BEGIN TRY DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) @@ -229,9 +258,9 @@ BEGIN TRY INSERT INTO @ResourceInfos ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId - FROM (SELECT TOP (@DummyTop) * FROM @Resources WHERE HasVersionToCompare = 1) A - LEFT OUTER JOIN dbo.Resource B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. - ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 + FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds WHERE HasVersionToCompare = 1) A + LEFT OUTER JOIN dbo.ResourceTbl B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. + ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <= PreviousVersion) From de5a156e2117720284d3f5acfb85acd3ce510748 Mon Sep 17 00:00:00 2001 From: SergeyGaluzo <95932081+SergeyGaluzo@users.noreply.github.com> Date: Wed, 16 Oct 2024 19:03:35 -0700 Subject: [PATCH 003/111] Merge history separation with separated raw resources (#4685) * History separation V0 * Forgotten resource * replace current by view * TRUNCATE * HardDelete * delete history v0 * missed 64 and removed dead code from SQL query generator * Removed history from current in merge * Triggers * tests and tran * disable/enable indexes * rollback hard delete and merge * rollback delete invisible history * TRUNCATE -> DELETE * line * leftovers * PK check * Cosmetic * WHERE nanes * Get resources with forced indexes * Removed redundant where * Adding feature flag for raw resource dedupping * Enable invisible history by default * parameters * commit * fixed typo * 65 + more realistic diff * adjusted update trigger * right trigger * next iteration * special chars * Added delete and update * \r * Adding script runner * Added verification * cosmetic * HOLDLOCK hint * removed incorrect comments * RT * lock timeout * 180 and remove empty * no changes in update resource search params * blob rewriter tool * Revert "no changes in update resource search params" This reverts commit b2e0c386d0e126ca265ff555d9f696d45e8cf9f5. * comment * Generic disable indexes and update search params * Dummy resources * fixes * Dummy records based on surr id * adjust test to filter dummy rows * exclude history and current * Adding PerfTest V-1 * Get asyn wrapper without type string to id function * tool * not exists on data copy * packages back * Added comments. * Correct filtered index on resource current * Added redundant IsHistory=0 to index * deduping * Removed dummy records * pp-p * history clause * deduping * testing parameters * get resource by type and surr id range with many versions * skip large databases * Added calls to fhir * added conflict * max retries = 3 * database pings * examples * reverse * start closer * put logic * Create * Move 65 to 84 * Fixes after merge * Adding RawResources table * change capture tweeks * Test fix * Added MI * inline insert * Repeat on updates --- .../HashingSqlQueryParameterManagerTests.cs | 4 +- .../Features/Schema/Migrations/84.diff.sql | 1 + .../Features/Schema/Migrations/84.sql | 5409 +++++++++++++++++ .../Features/Schema/SchemaVersion.cs | 1 + .../Features/Schema/SchemaVersionConstants.cs | 2 +- .../TransactionCheckWithInitialiScript.sql | 2 +- .../Schema/Sql/Sprocs/DisableIndexes.sql | 2 +- .../Schema/Sql/Sprocs/GetResources.sql | 10 +- .../Schema/Sql/Sprocs/MergeResources.sql | 2 +- .../Sql/Sprocs/UpdateResourceSearchParams.sql | 11 +- .../Features/Schema/Sql/Tables/Resource.sql | 138 +- .../Features/Schema/Sql/Views/Resource.sql | 119 + .../PrimaryKeyRangeParameterQueryGenerator.cs | 8 +- .../ResourceIdParameterQueryGenerator.cs | 2 +- ...ourceSurrogateIdParameterQueryGenerator.cs | 2 +- .../ResourceTypeIdParameterQueryGenerator.cs | 4 +- .../QueryGenerators/SqlQueryGenerator.cs | 184 +- .../Search/HashingSqlQueryParameterManager.cs | 2 +- .../Features/Search/SqlServerSearchService.cs | 19 +- .../Features/Storage/SqlStoreClient.cs | 30 +- .../Microsoft.Health.Fhir.SqlServer.csproj | 3 +- ...erFhirResourceChangeCaptureEnabledTests.cs | 6 +- .../Operations/Export/SqlServerExportTests.cs | 4 +- .../Persistence/FhirStorageTests.cs | 7 +- .../SqlServerFhirStorageTestHelper.cs | 8 +- .../SqlServerSchemaUpgradeTests.cs | 12 +- .../Persistence/SqlServerWatchdogTests.cs | 4 +- tools/BlobRewriter/BlobRewriter.csproj | 2 +- tools/PerfTester/App.config | 12 +- tools/PerfTester/Program.cs | 103 +- 30 files changed, 5848 insertions(+), 265 deletions(-) create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql diff --git a/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs b/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs index 93cb18f0f2..65cf597f55 100644 --- a/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs +++ b/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs @@ -34,8 +34,8 @@ public void GivenParametersThatShouldNotBeHashed_WhenAdded_ResultsInNoChangeToHa AssertDoesNotChangeHash(parameters, () => { parameters.AddParameter(1, includeInHash: false); - parameters.AddParameter(VLatest.Resource.ResourceId, "abc", false); - parameters.AddParameter(VLatest.Resource.ResourceId, (object)"123", false); + parameters.AddParameter(VLatest.ResourceCurrent.ResourceId, "abc", false); + parameters.AddParameter(VLatest.ResourceCurrent.ResourceId, (object)"123", false); }); Assert.False(parameters.HasParametersToHash); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql new file mode 100644 index 0000000000..2230e21194 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -0,0 +1 @@ +SET TRANSACTION ISOLATION LEVEL READ COMMITTED -- Not sure that it matters, but to gurantee that SQL versioning is not used -- Disable defrag UPDATE Parameters SET Number = 0 WHERE Id = 'DefragWatchdog.IsEnabled' EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Update',@Rows=@@rowcount,@Text='disable defrag' GO IF (SELECT sum(reserved_page_count*8.0/1024/1024) FROM sys.dm_db_partition_stats) > 2500 -- skip for large databases BEGIN INSERT INTO dbo.Parameters (Id, Number) SELECT 'SkipHistorySeparation', 1 EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Insert',@Rows=@@rowcount,@Text='SkipHistorySeparation' END GO ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalStartId bigint = NULL, @GlobalEndId bigint = NULL AS set nocount on DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') +' S='+isnull(convert(varchar,@StartId),'NULL') +' E='+isnull(convert(varchar,@EndId),'NULL') +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') -- Could this just be a boolean for if historical records should be returned? GlobalEndId should equal EndId in all cases I can think of. ,@st datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 BEGIN TRY DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) IF @GlobalEndId IS NOT NULL -- snapshot view BEGIN INSERT INTO @ResourceIds SELECT DISTINCT ResourceId FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND IsHistory = 1 AND IsDeleted = 0 OPTION (MAXDOP 1) IF @@rowcount > 0 INSERT INTO @SurrogateIds SELECT ResourceSurrogateId FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) -- w/o hint access to Resource table is inefficient when many versions are present. Hint is ignored if Resource is a view. WHERE ResourceTypeId = @ResourceTypeId AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId ) A WHERE RowId = 1 AND ResourceSurrogateId BETWEEN @StartId AND @EndId OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) END SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND IsHistory = 0 AND IsDeleted = 0 UNION ALL SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 AND IsDeleted = 0 OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; THROW END CATCH GO ALTER PROCEDURE dbo.DequeueJob @QueueType tinyint, @Worker varchar(100), @HeartbeatTimeoutSec int, @InputJobId bigint = NULL, @CheckTimeoutJobs bit = 0 AS set nocount on DECLARE @SP varchar(100) = 'DequeueJob' ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') +' H='+isnull(convert(varchar,@HeartbeatTimeoutSec),'NULL') +' W='+isnull(@Worker,'NULL') +' IJ='+isnull(convert(varchar,@InputJobId),'NULL') +' T='+isnull(convert(varchar,@CheckTimeoutJobs),'NULL') ,@Rows int = 0 ,@st datetime = getUTCdate() ,@JobId bigint ,@msg varchar(100) ,@Lock varchar(100) ,@PartitionId tinyint ,@MaxPartitions tinyint = 16 -- !!! hardcoded ,@LookedAtPartitions tinyint = 0 BEGIN TRY IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'DequeueJobStop' AND Number = 1) BEGIN EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=0,@Text='Skipped' RETURN END IF @InputJobId IS NULL SET @PartitionId = @MaxPartitions * rand() ELSE SET @PartitionId = @InputJobId % 16 SET TRANSACTION ISOLATION LEVEL READ COMMITTED WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions AND @CheckTimeoutJobs = 0 BEGIN SET @Lock = 'DequeueJob_'+convert(varchar,@QueueType)+'_'+convert(varchar,@PartitionId) BEGIN TRANSACTION EXECUTE sp_getapplock @Lock, 'Exclusive' UPDATE T SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = 1 -- running ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = T.JobId FROM dbo.JobQueue T WITH (PAGLOCK) JOIN (SELECT TOP 1 JobId FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 0 ORDER BY Priority ,JobId ) S ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId SET @Rows += @@rowcount COMMIT TRANSACTION IF @JobId IS NULL BEGIN SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END SET @LookedAtPartitions = @LookedAtPartitions + 1 END END -- Do timed out items. SET @LookedAtPartitions = 0 WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions BEGIN SET @Lock = 'DequeueStoreCopyWorkUnit_'+convert(varchar, @PartitionId) BEGIN TRANSACTION EXECUTE sp_getapplock @Lock, 'Exclusive' UPDATE T SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = CASE WHEN CancelRequested = 0 THEN 1 ELSE 4 END ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = CASE WHEN CancelRequested = 0 THEN T.JobId END ,Info = convert(varchar(1000),isnull(Info,'')+' Prev: Worker='+Worker+' Start='+convert(varchar,StartDate,121)) FROM dbo.JobQueue T WITH (PAGLOCK) JOIN (SELECT TOP 1 JobId FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 1 AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec ORDER BY Priority ,JobId ) S ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId SET @Rows += @@rowcount COMMIT TRANSACTION IF @JobId IS NULL BEGIN SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END SET @LookedAtPartitions = @LookedAtPartitions + 1 END END IF @InputJobId IS NOT NULL BEGIN UPDATE dbo.JobQueue WITH (PAGLOCK) SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = 1 -- running ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = JobId WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 0 AND JobId = @InputJobId SET @Rows += @@rowcount IF @JobId IS NULL BEGIN UPDATE dbo.JobQueue WITH (PAGLOCK) SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = 1 -- running ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = JobId WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 1 AND JobId = @InputJobId AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec SET @Rows += @@rowcount END END IF @JobId IS NOT NULL EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobId = @JobId SET @msg = 'J='+isnull(convert(varchar,@JobId),'NULL')+' P='+convert(varchar,@PartitionId) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows,@Text=@msg END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='DequeueJob',@Action='Alter' GO ALTER PROCEDURE dbo.GetActiveJobs @QueueType tinyint, @GroupId bigint = NULL AS set nocount on DECLARE @SP varchar(100) = 'GetActiveJobs' ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') +' G='+isnull(convert(varchar,@GroupId),'NULL') ,@st datetime = getUTCdate() ,@JobIds BigintList ,@PartitionId tinyint ,@MaxPartitions tinyint = 16 -- !!! hardcoded ,@LookedAtPartitions tinyint = 0 ,@Rows int = 0 BEGIN TRY SET @PartitionId = @MaxPartitions * rand() WHILE @LookedAtPartitions < @MaxPartitions BEGIN IF @GroupId IS NULL INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND Status IN (0,1) ELSE INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND GroupId = @GroupId AND Status IN (0,1) SET @Rows += @@rowcount SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END SET @LookedAtPartitions += 1 END IF @Rows > 0 EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='GetActiveJobs',@Action='Alter' GO INSERT INTO dbo.Parameters (Id, Char) SELECT 'HistorySeparation', 'LogEvent' EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Start' GO ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = 'GetResources' ,@InputRows int ,@DummyTop bigint = 9223372036854775807 ,@NotNullVersionExists bit ,@NullVersionExists bit ,@MinRT smallint ,@MaxRT smallint SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) BEGIN TRY IF @NotNullVersionExists = 1 IF @NullVersionExists = 0 SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) ELSE SELECT * FROM (SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 ) A OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) ELSE SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='GetResources',@Action='Alter' GO ALTER PROCEDURE dbo.MergeResources -- This stored procedure can be used for: -- 1. Ordinary put with single version per resource in input -- 2. Put with history preservation (multiple input versions per resource) -- 3. Copy from one gen2 store to another with ResourceSurrogateId preserved. @AffectedRows int = 0 OUT ,@RaiseExceptionOnConflict bit = 1 ,@IsResourceChangeCaptureEnabled bit = 0 ,@TransactionId bigint = NULL ,@SingleTransaction bit = 1 ,@Resources dbo.ResourceList READONLY ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY ,@TokenSearchParams dbo.TokenSearchParamList READONLY ,@TokenTexts dbo.TokenTextList READONLY ,@StringSearchParams dbo.StringSearchParamList READONLY ,@UriSearchParams dbo.UriSearchParamList READONLY ,@NumberSearchParams dbo.NumberSearchParamList READONLY ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY ,@DateTimeSearchParms dbo.DateTimeSearchParamList READONLY ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) ,@DummyTop bigint = 9223372036854775807 ,@InitialTranCount int = @@trancount ,@IsRetry bit = 0 DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') SET @AffectedRows = 0 BEGIN TRY DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) DECLARE @ResourceInfos AS TABLE ( ResourceTypeId smallint NOT NULL ,SurrogateId bigint NOT NULL ,Version int NOT NULL ,KeepHistory bit NOT NULL ,PreviousVersion int NULL ,PreviousSurrogateId bigint NULL PRIMARY KEY (ResourceTypeId, SurrogateId) ) DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 SET @SingleTransaction = 1 SET @Mode += ' ST='+convert(varchar,@SingleTransaction) -- perform retry check in transaction to hold locks IF @InitialTranCount = 0 BEGIN IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 ) BEGIN BEGIN TRANSACTION INSERT INTO @Existing ( ResourceTypeId, SurrogateId ) SELECT B.ResourceTypeId, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * FROM @Resources) A JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @@rowcount > 0 SET @IsRetry = 1 IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction END END SET @Mode += ' R='+convert(varchar,@IsRetry) IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION IF @IsRetry = 0 BEGIN INSERT INTO @ResourceInfos ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * FROM @Resources WHERE HasVersionToCompare = 1) A LEFT OUTER JOIN dbo.Resource B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <> PreviousVersion + 1) THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 INSERT INTO @PreviousSurrogateIds SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory FROM @ResourceInfos WHERE PreviousSurrogateId IS NOT NULL IF @@rowcount > 0 BEGIN UPDATE dbo.Resource SET IsHistory = 1 WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) SET @AffectedRows += @@rowcount IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) UPDATE dbo.Resource SET IsHistory = 1 ,RawResource = 0xF -- "invisible" value ,SearchParamHash = NULL ,HistoryTransactionId = @TransactionId WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) ELSE DELETE FROM dbo.Resource WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) SET @AffectedRows += @@rowcount DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenText WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.StringSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.UriSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.NumberSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.QuantitySearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.DateTimeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.ReferenceTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenDateTimeCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenQuantityCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenStringCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' END INSERT INTO dbo.Resource ( ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId ) SELECT ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId FROM @Resources SET @AffectedRows += @@rowcount INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion FROM @ReferenceSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow FROM @TokenSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenText ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text FROM @TokenTexts SET @AffectedRows += @@rowcount INSERT INTO dbo.StringSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax FROM @StringSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.UriSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri FROM @UriSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.NumberSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue FROM @NumberSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.QuantitySearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue FROM @QuantitySearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.DateTimeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax FROM @DateTimeSearchParms SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 FROM @ReferenceTokenCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 FROM @TokenTokenCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenDateTimeCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 FROM @TokenDateTimeCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenQuantityCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 FROM @TokenQuantityCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenStringCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 FROM @TokenStringCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenNumberNumberCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange FROM @TokenNumberNumberCompositeSearchParams SET @AffectedRows += @@rowcount END -- @IsRetry = 0 ELSE BEGIN -- @IsRetry = 1 INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM (SELECT TOP (@DummyTop) * FROM @ResourceWriteClaims) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.ResourceWriteClaim C WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow FROM (SELECT TOP (@DummyTop) * FROM @TokenSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenText ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text FROM (SELECT TOP (@DummyTop) * FROM @TokenTexts) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.StringSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax FROM (SELECT TOP (@DummyTop) * FROM @StringSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenText C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.UriSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri FROM (SELECT TOP (@DummyTop) * FROM @UriSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.UriSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.NumberSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue FROM (SELECT TOP (@DummyTop) * FROM @NumberSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.NumberSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.QuantitySearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue FROM (SELECT TOP (@DummyTop) * FROM @QuantitySearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.QuantitySearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.DateTimeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax FROM (SELECT TOP (@DummyTop) * FROM @DateTimeSearchParms) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 FROM (SELECT TOP (@DummyTop) * FROM @ReferenceTokenCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.DateTimeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 FROM (SELECT TOP (@DummyTop) * FROM @TokenTokenCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenTokenCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenDateTimeCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 FROM (SELECT TOP (@DummyTop) * FROM @TokenDateTimeCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenDateTimeCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenQuantityCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 FROM (SELECT TOP (@DummyTop) * FROM @TokenQuantityCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenQuantityCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenStringCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 FROM (SELECT TOP (@DummyTop) * FROM @TokenStringCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenStringCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenNumberNumberCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange FROM (SELECT TOP (@DummyTop) * FROM @TokenNumberNumberCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenNumberNumberCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount END IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. EXECUTE dbo.CaptureResourceIdsForChanges @Resources IF @TransactionId IS NOT NULL EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows END TRY BEGIN CATCH IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource''%' OR error_message() LIKE '%''dbo.ResourceCurrent''%' OR error_message() LIKE '%''dbo.ResourceHistory''%') -- handles old and separated tables THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; ELSE THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='MergeResources',@Action='Alter' GO ALTER PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT ,@Resources dbo.ResourceList READONLY ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY ,@TokenSearchParams dbo.TokenSearchParamList READONLY ,@TokenTexts dbo.TokenTextList READONLY ,@StringSearchParams dbo.StringSearchParamList READONLY ,@UriSearchParams dbo.UriSearchParamList READONLY ,@NumberSearchParams dbo.NumberSearchParamList READONLY ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY ,@DateTimeSearchParams dbo.DateTimeSearchParamList READONLY ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') ,@Rows int BEGIN TRY DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) BEGIN TRANSACTION -- Update the search parameter hash value in the main resource table -- Avoid join to enable update via view UPDATE A SET SearchParamHash = (SELECT SearchParamHash FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) FROM dbo.Resource A WHERE IsHistory = 0 AND EXISTS (SELECT * FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) SET @Rows = @@rowcount -- First, delete all the search params of the resources to reindex. DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.ReferenceSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- Next, insert all the new search params. INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims INSERT INTO dbo.ReferenceSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion FROM @ReferenceSearchParams INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow FROM @TokenSearchParams INSERT INTO dbo.TokenText ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text FROM @TokenTexts INSERT INTO dbo.StringSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax FROM @StringSearchParams INSERT INTO dbo.UriSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri FROM @UriSearchParams INSERT INTO dbo.NumberSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue FROM @NumberSearchParams INSERT INTO dbo.QuantitySearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue FROM @QuantitySearchParams INSERT INTO dbo.DateTimeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax FROM @DateTimeSearchParams INSERT INTO dbo.ReferenceTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 FROM @ReferenceTokenCompositeSearchParams INSERT INTO dbo.TokenTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 FROM @TokenTokenCompositeSearchParams INSERT INTO dbo.TokenDateTimeCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 FROM @TokenDateTimeCompositeSearchParams INSERT INTO dbo.TokenQuantityCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 FROM @TokenQuantityCompositeSearchParams INSERT INTO dbo.TokenStringCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 FROM @TokenStringCompositeSearchParams INSERT INTO dbo.TokenNumberNumberCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange FROM @TokenNumberNumberCompositeSearchParams COMMIT TRANSACTION SET @FailedResources = (SELECT count(*) FROM @Resources) - @Rows EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='UpdateResourceSearchParams',@Action='Alter' GO ALTER PROCEDURE dbo.DisableIndexes WITH EXECUTE AS 'dbo' AS set nocount on DECLARE @SP varchar(100) = 'DisableIndexes' ,@Mode varchar(200) = '' ,@st datetime = getUTCdate() ,@Tbl varchar(100) ,@Ind varchar(200) ,@Txt varchar(4000) BEGIN TRY EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start' DECLARE @Tables TABLE (Tbl varchar(100) PRIMARY KEY, Supported bit) INSERT INTO @Tables EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0 EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Tables',@Action='Insert',@Rows=@@rowcount DECLARE @Indexes TABLE (Tbl varchar(100), Ind varchar(200), TblId int, IndId int PRIMARY KEY (Tbl, Ind)) INSERT INTO @Indexes SELECT Tbl ,I.Name ,TblId ,I.index_id FROM (SELECT TblId = object_id(Tbl), Tbl FROM @Tables) O JOIN sys.indexes I ON I.object_id = TblId EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Insert',@Rows=@@rowcount INSERT INTO dbo.IndexProperties ( TableName, IndexName, PropertyName, PropertyValue ) SELECT Tbl, Ind, 'DATA_COMPRESSION', data_comp FROM (SELECT Tbl ,Ind ,data_comp = isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END FROM sys.partitions WHERE object_id = TblId AND index_id = IndId),'NONE') FROM @Indexes ) A WHERE NOT EXISTS (SELECT * FROM dbo.IndexProperties WHERE TableName = Tbl AND IndexName = Ind) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='IndexProperties',@Action='Insert',@Rows=@@rowcount DELETE FROM @Indexes WHERE Tbl IN ('Resource','ResourceCurrent','ResourceHistory') OR IndId = 1 EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Delete',@Rows=@@rowcount WHILE EXISTS (SELECT * FROM @Indexes) BEGIN SELECT TOP 1 @Tbl = Tbl, @Ind = Ind FROM @Indexes SET @Txt = 'ALTER INDEX '+@Ind+' ON dbo.'+@Tbl+' DISABLE' EXECUTE(@Txt) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target=@Ind,@Action='Disable',@Text=@Txt DELETE FROM @Indexes WHERE Tbl = @Tbl AND Ind = @Ind END EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='DisableIndexes',@Action='Alter' GO IF object_id('dbo.ResourceCurrent') IS NULL BEGIN BEGIN TRY BEGIN TRANSACTION CREATE TABLE dbo.ResourceCurrent ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ,Version int NOT NULL ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceCurrent_RawResource_Length CHECK (RawResource > 0x0) ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL -- used for main CRUD operation CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceId UNIQUE (ResourceTypeId, ResourceId) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) ALTER TABLE dbo.ResourceCurrent SET ( LOCK_ESCALATION = AUTO ) CREATE UNIQUE INDEX IXU_ResourceTypeId_ResourceSurrogateId_WHERE_IsHistory_0_IsDeleted_0 ON dbo.ResourceCurrent (ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 AND IsDeleted = 0 ON PartitionScheme_ResourceTypeId (ResourceTypeId) CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceCurrent',@Action='Create' CREATE TABLE dbo.ResourceHistory ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ,Version int NOT NULL ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1, CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceHistory_RawResource_Length CHECK (RawResource > 0x0) ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL -- used for main CRUD operation ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) ALTER TABLE dbo.ResourceHistory SET ( LOCK_ESCALATION = AUTO ) CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceHistory',@Action='Create' COMMIT TRANSACTION END TRY BEGIN CATCH ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; THROW END CATCH END GO IF EXISTS (SELECT * FROM sys.objects WHERE object_id = object_id('dbo.Resource') AND type = 'u') AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'SkipHistorySeparation' AND Number = 1) BEGIN --CREATE TRIGGER dbo.ResourceIns EXECUTE(' CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource AFTER INSERT AS BEGIN INSERT INTO dbo.ResourceCurrent ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM Inserted WHERE IsHistory = 0 INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' --CREATE TRIGGER dbo.ResourceUpd EXECUTE(' CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource AFTER UPDATE AS BEGIN UPDATE B SET SearchParamHash = A.SearchParamHash -- this is the only update we support FROM Inserted A JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE A.IsHistory = 0 DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' --CREATE TRIGGER dbo.ResourceDel EXECUTE(' CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource AFTER DELETE AS BEGIN DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) DELETE FROM A FROM dbo.ResourceHistory A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' DECLARE @Types TABLE (ResourceTypeId smallint PRIMARY KEY, Name varchar(100)) DECLARE @MaxSurrogateId bigint = 0 ,@ResourceTypeId smallint IF NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') -- DELETE FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId' BEGIN DECLARE @MaxSurrogateIdTmp bigint INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes WHILE EXISTS (SELECT * FROM @Types) BEGIN SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types) SET @MaxSurrogateIdTmp = (SELECT max(ResourceSurrogateId) FROM Resource WHERE ResourceTypeId = @ResourceTypeId) IF @MaxSurrogateIdTmp > @MaxSurrogateId SET @MaxSurrogateId = @MaxSurrogateIdTmp DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId END INSERT INTO dbo.Parameters (Id, Bigint) SELECT 'HistorySeparation.MaxSurrogateId', @MaxSurrogateId END SET @MaxSurrogateId = (SELECT Bigint FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='@MaxSurrogateId',@Action='Select',@Text=@MaxSurrogateId -- Copy start ---------------------------------------------------------------------------------------------------------- DECLARE @Process varchar(100) = 'HistorySeparation.CopyResources' ,@Id varchar(100) = 'HistorySeparation.CopyResources.LastProcessed.TypeId.SurrogateId' ,@SurrogateId bigint ,@RowsToProcess int ,@ProcessedResources int ,@ReportDate datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 ,@Rows int ,@CurrentMaxSurrogateId bigint ,@LastProcessed varchar(100) ,@st datetime BEGIN TRY INSERT INTO dbo.Parameters (Id, Char) SELECT @Process, 'LogEvent' EXECUTE dbo.LogEvent @Process=@Process,@Status='Start' INSERT INTO dbo.Parameters (Id, Char) SELECT @Id, '0.0' WHERE NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = @Id) SET @LastProcessed = (SELECT Char FROM dbo.Parameters WHERE Id = @Id) INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Insert',@Rows=@@rowcount SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 1) SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 2) DELETE FROM @Types WHERE ResourceTypeId < @ResourceTypeId EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Delete',@Rows=@@rowcount WHILE EXISTS (SELECT * FROM @Types) -- Processing in ASC order BEGIN SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types ORDER BY ResourceTypeId) SET @ProcessedResources = 0 SET @CurrentMaxSurrogateId = 0 WHILE @CurrentMaxSurrogateId IS NOT NULL BEGIN BEGIN TRANSACTION SET @CurrentMaxSurrogateId = NULL SELECT @CurrentMaxSurrogateId = max(ResourceSurrogateId), @RowsToProcess = count(*) FROM (SELECT TOP 5000 ResourceSurrogateId -- 5000 is max to avoid lock escalation FROM dbo.Resource (HOLDLOCK) -- Hold locks for the duration of 2 inserts, so other write transactions cannot change data WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @MaxSurrogateId ORDER BY ResourceSurrogateId ) A IF @CurrentMaxSurrogateId IS NOT NULL BEGIN SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@CurrentMaxSurrogateId) SET @st = getUTCdate() INSERT INTO dbo.ResourceCurrent ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM (SELECT * FROM dbo.Resource A WITH (INDEX = 1) WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND IsHistory = 0 ) A WHERE NOT EXISTS (SELECT * FROM dbo.ResourceCurrent B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- surr id from $import insert can point in the past OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceCurrent',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st SET @st = getUTCdate() INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM (SELECT TOP (@DummyTop) * FROM dbo.Resource A WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND IsHistory = 1 ) A WHERE NOT EXISTS (SELECT * FROM dbo.ResourceHistory B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- history can be inserted by the new version insert in merge OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceHistory',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id COMMIT TRANSACTION SET @SurrogateId = @CurrentMaxSurrogateId SET @ProcessedResources += @RowsToProcess IF datediff(second, @ReportDate, getUTCdate()) > 60 BEGIN EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources SET @ReportDate = getUTCdate() SET @ProcessedResources = 0 END END ELSE BEGIN COMMIT TRANSACTION SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@MaxSurrogateId) UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id END END IF @ProcessedResources > 0 EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId SET @SurrogateId = 0 END EXECUTE dbo.LogEvent @Process=@Process,@Status='End' END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; THROW END CATCH -- Copy end ---------------------------------------------------------------------------------------------------------- DECLARE @OldRows bigint ,@CurrentRows bigint ,@HistoryRows bigint ,@msg varchar(1000) BEGIN TRY BEGIN TRANSACTION -- verification -- lock input SET @OldRows = (SELECT TOP 1 1 FROM dbo.Resource (TABLOCKX)) SET @OldRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('Resource') AND index_id IN (0,1)) EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='Resource',@Action='RowsCheck',@Text=@OldRows SET @CurrentRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceCurrent') AND index_id IN (0,1)) EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceCurrent',@Action='RowsCheck',@Text=@CurrentRows SET @HistoryRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceHistory') AND index_id IN (0,1)) EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceHistory',@Action='RowsCheck',@Text=@HistoryRows IF @CurrentRows + @HistoryRows <> @OldRows BEGIN SET @msg = 'OldRows='+convert(varchar,@OldRows)+' <> NewRows='+convert(varchar,@CurrentRows + @HistoryRows) RAISERROR(@msg,18,127) END COMMIT TRANSACTION -- verification EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Text='Completed' EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Started' SET lock_timeout 180000 -- 3 minutes BEGIN TRANSACTION -- table - view switch IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'KeepResourceTable' AND Number = 1) EXECUTE sp_rename 'Resource', 'Resource_Table' ELSE DROP TABLE dbo.Resource --CREATE VIEW dbo.Resource EXECUTE(' CREATE VIEW dbo.Resource AS SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsHistory ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM dbo.ResourceHistory UNION ALL SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsHistory ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,NULL FROM dbo.ResourceCurrent ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='Resource',@Action='Create' IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceIns' AND type = 'tr') DROP TRIGGER dbo.ResourceIns --CREATE TRIGGER dbo.ResourceIns EXECUTE(' CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT AS BEGIN INSERT INTO dbo.ResourceCurrent ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM Inserted WHERE IsHistory = 0 INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceUpd' AND type = 'tr') DROP TRIGGER dbo.ResourceUpd --CREATE TRIGGER dbo.ResourceUpd EXECUTE(' CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE AS BEGIN IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) BEGIN UPDATE B SET SearchParamHash = A.SearchParamHash -- this is the only update we support FROM Inserted A JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE A.IsHistory = 0 RETURN END IF NOT UPDATE(IsHistory) RAISERROR(''Generic updates are not supported via Resource view'',18,127) DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceDel' AND type = 'tr') DROP TRIGGER dbo.ResourceDel --CREATE TRIGGER dbo.ResourceDel EXECUTE(' CREATE TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE AS BEGIN DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) DELETE FROM A FROM dbo.ResourceHistory A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' COMMIT TRANSACTION -- table - view switch EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Completed' END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; THROW END CATCH END GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='End' GO \ No newline at end of file diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql new file mode 100644 index 0000000000..36d047ac78 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -0,0 +1,5409 @@ + +/************************************************************************************************* + Auto-Generated from Sql build task. Do not manually edit it. +**************************************************************************************************/ +SET XACT_ABORT ON +BEGIN TRAN +IF EXISTS (SELECT * + FROM sys.tables + WHERE name = 'ClaimType') + BEGIN + ROLLBACK; + RETURN; + END + + +GO +INSERT INTO dbo.SchemaVersion +VALUES (84, 'started'); + +CREATE PARTITION FUNCTION PartitionFunction_ResourceTypeId(SMALLINT) + AS RANGE RIGHT + FOR VALUES (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150); + +CREATE PARTITION SCHEME PartitionScheme_ResourceTypeId + AS PARTITION PartitionFunction_ResourceTypeId + ALL TO ([PRIMARY]); + + +GO +CREATE PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp(DATETIME2 (7)) + AS RANGE RIGHT + FOR VALUES (N'1970-01-01T00:00:00.0000000'); + +CREATE PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp + AS PARTITION PartitionFunction_ResourceChangeData_Timestamp + ALL TO ([PRIMARY]); + +DECLARE @numberOfHistoryPartitions AS INT = 48; + +DECLARE @numberOfFuturePartitions AS INT = 720; + +DECLARE @rightPartitionBoundary AS DATETIME2 (7); + +DECLARE @currentDateTime AS DATETIME2 (7) = sysutcdatetime(); + +WHILE @numberOfHistoryPartitions >= -@numberOfFuturePartitions + BEGIN + SET @rightPartitionBoundary = DATEADD(hour, DATEDIFF(hour, 0, @currentDateTime) - @numberOfHistoryPartitions, 0); + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [Primary]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@rightPartitionBoundary); + SET @numberOfHistoryPartitions -= 1; + END + +CREATE SEQUENCE dbo.ResourceSurrogateIdUniquifierSequence + AS INT + START WITH 0 + INCREMENT BY 1 + MINVALUE 0 + MAXVALUE 79999 + CYCLE + CACHE 1000000; + +CREATE TYPE dbo.BigintList AS TABLE ( + Id BIGINT NOT NULL PRIMARY KEY); + +CREATE TYPE dbo.DateTimeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + StartDateTime DATETIMEOFFSET (7) NOT NULL, + EndDateTime DATETIMEOFFSET (7) NOT NULL, + IsLongerThanADay BIT NOT NULL, + IsMin BIT NOT NULL, + IsMax BIT NOT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax)); + +CREATE TYPE dbo.NumberSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NULL, + HighValue DECIMAL (36, 18) NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue)); + +CREATE TYPE dbo.QuantitySearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + QuantityCodeId INT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NULL, + HighValue DECIMAL (36, 18) NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue)); + +CREATE TYPE dbo.ReferenceSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId)); + +CREATE TYPE dbo.ReferenceTokenCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri1 VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId1 SMALLINT NULL, + ReferenceResourceId1 VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion1 INT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.ResourceDateKeyList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ResourceSurrogateId BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId, ResourceSurrogateId)); + +CREATE TYPE dbo.ResourceKeyList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NULL UNIQUE (ResourceTypeId, ResourceId, Version)); + +CREATE TYPE dbo.ResourceList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + HasVersionToCompare BIT NOT NULL, + IsDeleted BIT NOT NULL, + IsHistory BIT NOT NULL, + KeepHistory BIT NOT NULL, + RawResource VARBINARY (MAX) NOT NULL, + IsRawResourceMetaSet BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + SearchParamHash VARCHAR (64) NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), + UNIQUE (ResourceTypeId, ResourceId, Version)); + +CREATE TYPE dbo.ResourceWriteClaimList AS TABLE ( + ResourceSurrogateId BIGINT NOT NULL, + ClaimTypeId TINYINT NOT NULL, + ClaimValue NVARCHAR (128) NOT NULL); + +CREATE TYPE dbo.StringList AS TABLE ( + String VARCHAR (MAX)); + +CREATE TYPE dbo.StringSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL, + IsMin BIT NOT NULL, + IsMax BIT NOT NULL); + +CREATE TYPE dbo.TokenDateTimeCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + StartDateTime2 DATETIMEOFFSET (7) NOT NULL, + EndDateTime2 DATETIMEOFFSET (7) NOT NULL, + IsLongerThanADay2 BIT NOT NULL); + +CREATE TYPE dbo.TokenNumberNumberCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + SingleValue3 DECIMAL (36, 18) NULL, + LowValue3 DECIMAL (36, 18) NULL, + HighValue3 DECIMAL (36, 18) NULL, + HasRange BIT NOT NULL); + +CREATE TYPE dbo.TokenQuantityCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SystemId2 INT NULL, + QuantityCodeId2 INT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL); + +CREATE TYPE dbo.TokenSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + Code VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.TokenStringCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + Text2 NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow2 NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL); + +CREATE TYPE dbo.TokenTextList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (400) COLLATE Latin1_General_CI_AI NOT NULL); + +CREATE TYPE dbo.TokenTokenCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.SearchParamTableType_2 AS TABLE ( + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (20) NOT NULL, + IsPartiallySupported BIT NOT NULL); + +CREATE TYPE dbo.BulkReindexResourceTableType_1 AS TABLE ( + Offset INT NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ETag INT NULL, + SearchParamHash VARCHAR (64) NOT NULL); + +CREATE TYPE dbo.UriSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri)); + +CREATE TABLE dbo.ClaimType ( + ClaimTypeId TINYINT IDENTITY (1, 1) NOT NULL, + Name VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_ClaimType_ClaimTypeId UNIQUE (ClaimTypeId), + CONSTRAINT PKC_ClaimType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.CompartmentAssignment ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + CompartmentTypeId TINYINT NOT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + IsHistory BIT NOT NULL, + CONSTRAINT PKC_CompartmentAssignment PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId, CompartmentTypeId, ReferenceResourceId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + + +GO +ALTER TABLE dbo.CompartmentAssignment + ADD CONSTRAINT DF_CompartmentAssignment_IsHistory DEFAULT 0 FOR IsHistory; + + +GO +ALTER TABLE dbo.CompartmentAssignment SET (LOCK_ESCALATION = AUTO); + + +GO +CREATE NONCLUSTERED INDEX IX_CompartmentAssignment_CompartmentTypeId_ReferenceResourceId + ON dbo.CompartmentAssignment(ResourceTypeId, CompartmentTypeId, ReferenceResourceId, ResourceSurrogateId) WHERE IsHistory = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.CompartmentType ( + CompartmentTypeId TINYINT IDENTITY (1, 1) NOT NULL, + Name VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_CompartmentType_CompartmentTypeId UNIQUE (CompartmentTypeId), + CONSTRAINT PKC_CompartmentType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.DateTimeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + StartDateTime DATETIME2 (7) NOT NULL, + EndDateTime DATETIME2 (7) NOT NULL, + IsLongerThanADay BIT NOT NULL, + IsMin BIT CONSTRAINT date_IsMin_Constraint DEFAULT 0 NOT NULL, + IsMax BIT CONSTRAINT date_IsMax_Constraint DEFAULT 0 NOT NULL +); + +ALTER TABLE dbo.DateTimeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_DateTimeSearchParam + ON dbo.DateTimeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_StartDateTime_EndDateTime_INCLUDE_IsLongerThanADay_IsMin_IsMax + ON dbo.DateTimeSearchParam(SearchParamId, StartDateTime, EndDateTime) + INCLUDE(IsLongerThanADay, IsMin, IsMax) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_EndDateTime_StartDateTime_INCLUDE_IsLongerThanADay_IsMin_IsMax + ON dbo.DateTimeSearchParam(SearchParamId, EndDateTime, StartDateTime) + INCLUDE(IsLongerThanADay, IsMin, IsMax) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_StartDateTime_EndDateTime_INCLUDE_IsMin_IsMax_WHERE_IsLongerThanADay_1 + ON dbo.DateTimeSearchParam(SearchParamId, StartDateTime, EndDateTime) + INCLUDE(IsMin, IsMax) WHERE IsLongerThanADay = 1 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_EndDateTime_StartDateTime_INCLUDE_IsMin_IsMax_WHERE_IsLongerThanADay_1 + ON dbo.DateTimeSearchParam(SearchParamId, EndDateTime, StartDateTime) + INCLUDE(IsMin, IsMax) WHERE IsLongerThanADay = 1 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +IF NOT EXISTS (SELECT 1 + FROM sys.tables + WHERE name = 'EventAgentCheckpoint') + BEGIN + CREATE TABLE dbo.EventAgentCheckpoint ( + CheckpointId VARCHAR (64) NOT NULL, + LastProcessedDateTime DATETIMEOFFSET (7), + LastProcessedIdentifier VARCHAR (64) , + UpdatedOn DATETIME2 (7) DEFAULT sysutcdatetime() NOT NULL, + CONSTRAINT PK_EventAgentCheckpoint PRIMARY KEY CLUSTERED (CheckpointId) + ) ON [PRIMARY]; + END + +CREATE PARTITION FUNCTION EventLogPartitionFunction(TINYINT) + AS RANGE RIGHT + FOR VALUES (0, 1, 2, 3, 4, 5, 6, 7); + + +GO +CREATE PARTITION SCHEME EventLogPartitionScheme + AS PARTITION EventLogPartitionFunction + ALL TO ([PRIMARY]); + + +GO +CREATE TABLE dbo.EventLog ( + PartitionId AS isnull(CONVERT (TINYINT, EventId % 8), 0) PERSISTED, + EventId BIGINT IDENTITY (1, 1) NOT NULL, + EventDate DATETIME NOT NULL, + Process VARCHAR (100) NOT NULL, + Status VARCHAR (10) NOT NULL, + Mode VARCHAR (200) NULL, + Action VARCHAR (20) NULL, + Target VARCHAR (100) NULL, + Rows BIGINT NULL, + Milliseconds INT NULL, + EventText NVARCHAR (3500) NULL, + SPID SMALLINT NOT NULL, + HostName VARCHAR (64) NOT NULL CONSTRAINT PKC_EventLog_EventDate_EventId_PartitionId PRIMARY KEY CLUSTERED (EventDate, EventId, PartitionId) ON EventLogPartitionScheme (PartitionId) +); + +CREATE TABLE dbo.ExportJob ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Hash VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (10) NOT NULL, + HeartbeatDateTime DATETIME2 (7) NULL, + RawJobRecord VARCHAR (MAX) NOT NULL, + JobVersion ROWVERSION NOT NULL, + CONSTRAINT PKC_ExportJob PRIMARY KEY CLUSTERED (Id) +); + +CREATE UNIQUE NONCLUSTERED INDEX IX_ExportJob_Hash_Status_HeartbeatDateTime + ON dbo.ExportJob(Hash, Status, HeartbeatDateTime); + +CREATE TABLE dbo.IndexProperties ( + TableName VARCHAR (100) NOT NULL, + IndexName VARCHAR (200) NOT NULL, + PropertyName VARCHAR (100) NOT NULL, + PropertyValue VARCHAR (100) NOT NULL, + CreateDate DATETIME CONSTRAINT DF_IndexProperties_CreateDate DEFAULT getUTCdate() NOT NULL CONSTRAINT PKC_IndexProperties_TableName_IndexName_PropertyName PRIMARY KEY CLUSTERED (TableName, IndexName, PropertyName) +); + +CREATE PARTITION FUNCTION TinyintPartitionFunction(TINYINT) + AS RANGE RIGHT + FOR VALUES (0, 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150, 151, 152, 153, 154, 155, 156, 157, 158, 159, 160, 161, 162, 163, 164, 165, 166, 167, 168, 169, 170, 171, 172, 173, 174, 175, 176, 177, 178, 179, 180, 181, 182, 183, 184, 185, 186, 187, 188, 189, 190, 191, 192, 193, 194, 195, 196, 197, 198, 199, 200, 201, 202, 203, 204, 205, 206, 207, 208, 209, 210, 211, 212, 213, 214, 215, 216, 217, 218, 219, 220, 221, 222, 223, 224, 225, 226, 227, 228, 229, 230, 231, 232, 233, 234, 235, 236, 237, 238, 239, 240, 241, 242, 243, 244, 245, 246, 247, 248, 249, 250, 251, 252, 253, 254, 255); + + +GO +CREATE PARTITION SCHEME TinyintPartitionScheme + AS PARTITION TinyintPartitionFunction + ALL TO ([PRIMARY]); + + +GO +CREATE TABLE dbo.JobQueue ( + QueueType TINYINT NOT NULL, + GroupId BIGINT NOT NULL, + JobId BIGINT NOT NULL, + PartitionId AS CONVERT (TINYINT, JobId % 16) PERSISTED, + Definition VARCHAR (MAX) NOT NULL, + DefinitionHash VARBINARY (20) NOT NULL, + Version BIGINT CONSTRAINT DF_JobQueue_Version DEFAULT datediff_big(millisecond, '0001-01-01', getUTCdate()) NOT NULL, + Status TINYINT CONSTRAINT DF_JobQueue_Status DEFAULT 0 NOT NULL, + Priority TINYINT CONSTRAINT DF_JobQueue_Priority DEFAULT 100 NOT NULL, + Data BIGINT NULL, + Result VARCHAR (MAX) NULL, + CreateDate DATETIME CONSTRAINT DF_JobQueue_CreateDate DEFAULT getUTCdate() NOT NULL, + StartDate DATETIME NULL, + EndDate DATETIME NULL, + HeartbeatDate DATETIME CONSTRAINT DF_JobQueue_HeartbeatDate DEFAULT getUTCdate() NOT NULL, + Worker VARCHAR (100) NULL, + Info VARCHAR (1000) NULL, + CancelRequested BIT CONSTRAINT DF_JobQueue_CancelRequested DEFAULT 0 NOT NULL CONSTRAINT PKC_JobQueue_QueueType_PartitionId_JobId PRIMARY KEY CLUSTERED (QueueType, PartitionId, JobId) ON TinyintPartitionScheme (QueueType), + CONSTRAINT U_JobQueue_QueueType_JobId UNIQUE (QueueType, JobId) +); + + +GO +CREATE INDEX IX_QueueType_PartitionId_Status_Priority + ON dbo.JobQueue(PartitionId, Status, Priority) + ON TinyintPartitionScheme (QueueType); + + +GO +CREATE INDEX IX_QueueType_GroupId + ON dbo.JobQueue(QueueType, GroupId) + ON TinyintPartitionScheme (QueueType); + + +GO +CREATE INDEX IX_QueueType_DefinitionHash + ON dbo.JobQueue(QueueType, DefinitionHash) + ON TinyintPartitionScheme (QueueType); + +CREATE TABLE dbo.NumberSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NOT NULL, + HighValue DECIMAL (36, 18) NOT NULL +); + +ALTER TABLE dbo.NumberSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_NumberSearchParam + ON dbo.NumberSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_SingleValue_WHERE_SingleValue_NOT_NULL + ON dbo.NumberSearchParam(SearchParamId, SingleValue) WHERE SingleValue IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_LowValue_HighValue + ON dbo.NumberSearchParam(SearchParamId, LowValue, HighValue) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_HighValue_LowValue + ON dbo.NumberSearchParam(SearchParamId, HighValue, LowValue) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.Parameters ( + Id VARCHAR (100) NOT NULL, + Date DATETIME NULL, + Number FLOAT NULL, + Bigint BIGINT NULL, + Char VARCHAR (4000) NULL, + Binary VARBINARY (MAX) NULL, + UpdatedDate DATETIME NULL, + UpdatedBy NVARCHAR (255) NULL CONSTRAINT PKC_Parameters_Id PRIMARY KEY CLUSTERED (Id) WITH (IGNORE_DUP_KEY = ON) +); + + +GO +CREATE TABLE dbo.ParametersHistory ( + ChangeId INT IDENTITY (1, 1) NOT NULL, + Id VARCHAR (100) NOT NULL, + Date DATETIME NULL, + Number FLOAT NULL, + Bigint BIGINT NULL, + Char VARCHAR (4000) NULL, + Binary VARBINARY (MAX) NULL, + UpdatedDate DATETIME NULL, + UpdatedBy NVARCHAR (255) NULL +); + +CREATE TABLE dbo.QuantityCode ( + QuantityCodeId INT IDENTITY (1, 1) NOT NULL, + Value NVARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_QuantityCode_QuantityCodeId UNIQUE (QuantityCodeId), + CONSTRAINT PKC_QuantityCode PRIMARY KEY CLUSTERED (Value) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.QuantitySearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + QuantityCodeId INT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NOT NULL, + HighValue DECIMAL (36, 18) NOT NULL +); + +ALTER TABLE dbo.QuantitySearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_QuantitySearchParam + ON dbo.QuantitySearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_SingleValue_INCLUDE_SystemId_WHERE_SingleValue_NOT_NULL + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, SingleValue) + INCLUDE(SystemId) WHERE SingleValue IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_LowValue_HighValue_INCLUDE_SystemId + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, LowValue, HighValue) + INCLUDE(SystemId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_HighValue_LowValue_INCLUDE_SystemId + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, HighValue, LowValue) + INCLUDE(SystemId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReferenceSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion INT NULL +); + +ALTER TABLE dbo.ReferenceSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_ReferenceSearchParam + ON dbo.ReferenceSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE INDEX IXU_ReferenceResourceId_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.ReferenceSearchParam(ReferenceResourceId, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReferenceTokenCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri1 VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId1 SMALLINT NULL, + ReferenceResourceId1 VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion1 INT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.ReferenceTokenCompositeSearchParam + ADD CONSTRAINT CHK_ReferenceTokenCompositeSearchParam_CodeOverflow2 CHECK (LEN(Code2) = 256 + OR CodeOverflow2 IS NULL); + +ALTER TABLE dbo.ReferenceTokenCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_ReferenceTokenCompositeSearchParam + ON dbo.ReferenceTokenCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_ReferenceResourceId1_Code2_INCLUDE_ReferenceResourceTypeId1_BaseUri1_SystemId2 + ON dbo.ReferenceTokenCompositeSearchParam(SearchParamId, ReferenceResourceId1, Code2) + INCLUDE(ReferenceResourceTypeId1, BaseUri1, SystemId2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReindexJob ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (10) NOT NULL, + HeartbeatDateTime DATETIME2 (7) NULL, + RawJobRecord VARCHAR (MAX) NOT NULL, + JobVersion ROWVERSION NOT NULL, + CONSTRAINT PKC_ReindexJob PRIMARY KEY CLUSTERED (Id) +); + +CREATE TABLE dbo.RawResources ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + RawResource VARBINARY (MAX) NULL CONSTRAINT PKC_RawResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.RawResources SET (LOCK_ESCALATION = AUTO); + + +GO +CREATE TABLE dbo.ResourceCurrent ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + IsHistory BIT CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0 NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), + CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceId UNIQUE (ResourceTypeId, ResourceId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.ResourceCurrent SET (LOCK_ESCALATION = AUTO); + +CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL + ON dbo.ResourceCurrent(ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL + ON dbo.ResourceCurrent(ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + + +GO +EXECUTE sp_rename 'ResourceCurrent', 'ResourceCurrentTbl'; + + +GO +CREATE VIEW dbo.ResourceCurrent +AS +SELECT A.ResourceTypeId, + A.ResourceSurrogateId, + ResourceId, + Version, + IsHistory, + IsDeleted, + RequestMethod, + B.RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId +FROM dbo.ResourceCurrentTbl AS A + LEFT OUTER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + + +GO +CREATE TABLE dbo.ResourceHistory ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + IsHistory BIT CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1 NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1), + CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.ResourceHistory SET (LOCK_ESCALATION = AUTO); + +CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL + ON dbo.ResourceHistory(ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL + ON dbo.ResourceHistory(ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + + +GO +EXECUTE sp_rename 'ResourceHistory', 'ResourceHistoryTbl'; + + +GO +CREATE VIEW dbo.ResourceHistory +AS +SELECT A.ResourceTypeId, + A.ResourceSurrogateId, + ResourceId, + Version, + IsHistory, + IsDeleted, + RequestMethod, + B.RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId +FROM dbo.ResourceHistoryTbl AS A + LEFT OUTER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + + +GO +CREATE TABLE dbo.Dummy ( + Dummy INT +); + +CREATE TABLE dbo.ResourceChangeData ( + Id BIGINT IDENTITY (1, 1) NOT NULL, + Timestamp DATETIME2 (7) CONSTRAINT DF_ResourceChangeData_Timestamp DEFAULT sysutcdatetime() NOT NULL, + ResourceId VARCHAR (64) NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceVersion INT NOT NULL, + ResourceChangeTypeId TINYINT NOT NULL +) ON PartitionScheme_ResourceChangeData_Timestamp (Timestamp); + +CREATE CLUSTERED INDEX IXC_ResourceChangeData + ON dbo.ResourceChangeData(Id ASC) WITH (ONLINE = ON) + ON PartitionScheme_ResourceChangeData_Timestamp (Timestamp); + +CREATE TABLE dbo.ResourceChangeDataStaging ( + Id BIGINT IDENTITY (1, 1) NOT NULL, + Timestamp DATETIME2 (7) CONSTRAINT DF_ResourceChangeDataStaging_Timestamp DEFAULT sysutcdatetime() NOT NULL, + ResourceId VARCHAR (64) NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceVersion INT NOT NULL, + ResourceChangeTypeId TINYINT NOT NULL +) ON [PRIMARY]; + +CREATE CLUSTERED INDEX IXC_ResourceChangeDataStaging + ON dbo.ResourceChangeDataStaging(Id ASC, Timestamp ASC) WITH (ONLINE = ON) + ON [PRIMARY]; + +ALTER TABLE dbo.ResourceChangeDataStaging WITH CHECK + ADD CONSTRAINT CHK_ResourceChangeDataStaging_partition CHECK (Timestamp < CONVERT (DATETIME2 (7), N'9999-12-31 23:59:59.9999999')); + +ALTER TABLE dbo.ResourceChangeDataStaging CHECK CONSTRAINT CHK_ResourceChangeDataStaging_partition; + +CREATE TABLE dbo.ResourceChangeType ( + ResourceChangeTypeId TINYINT NOT NULL, + Name NVARCHAR (50) NOT NULL, + CONSTRAINT PK_ResourceChangeType PRIMARY KEY CLUSTERED (ResourceChangeTypeId), + CONSTRAINT UQ_ResourceChangeType_Name UNIQUE NONCLUSTERED (Name) +) ON [PRIMARY]; + + +GO +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (0, N'Creation'); + +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (1, N'Update'); + +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (2, N'Deletion'); + +CREATE TABLE dbo.ResourceType ( + ResourceTypeId SMALLINT IDENTITY (1, 1) NOT NULL, + Name NVARCHAR (50) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_ResourceType_ResourceTypeId UNIQUE (ResourceTypeId), + CONSTRAINT PKC_ResourceType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.ResourceWriteClaim ( + ResourceSurrogateId BIGINT NOT NULL, + ClaimTypeId TINYINT NOT NULL, + ClaimValue NVARCHAR (128) NOT NULL +) +WITH (DATA_COMPRESSION = PAGE); + +CREATE CLUSTERED INDEX IXC_ResourceWriteClaim + ON dbo.ResourceWriteClaim(ResourceSurrogateId, ClaimTypeId); + +CREATE TABLE dbo.SchemaMigrationProgress ( + Timestamp DATETIME2 (3) DEFAULT CURRENT_TIMESTAMP, + Message NVARCHAR (MAX) +); + +CREATE TABLE dbo.SearchParam ( + SearchParamId SMALLINT IDENTITY (1, 1) NOT NULL, + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (20) NULL, + LastUpdated DATETIMEOFFSET (7) NULL, + IsPartiallySupported BIT NULL, + CONSTRAINT UQ_SearchParam_SearchParamId UNIQUE (SearchParamId), + CONSTRAINT PKC_SearchParam PRIMARY KEY CLUSTERED (Uri) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.StringSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL, + IsMin BIT CONSTRAINT string_IsMin_Constraint DEFAULT 0 NOT NULL, + IsMax BIT CONSTRAINT string_IsMax_Constraint DEFAULT 0 NOT NULL +); + +ALTER TABLE dbo.StringSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_StringSearchParam + ON dbo.StringSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Text_INCLUDE_TextOverflow_IsMin_IsMax + ON dbo.StringSearchParam(SearchParamId, Text) + INCLUDE(TextOverflow, IsMin, IsMax) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Text_INCLUDE_IsMin_IsMax_WHERE_TextOverflow_NOT_NULL + ON dbo.StringSearchParam(SearchParamId, Text) + INCLUDE(IsMin, IsMax) WHERE TextOverflow IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.System ( + SystemId INT IDENTITY (1, 1) NOT NULL, + Value NVARCHAR (256) NOT NULL, + CONSTRAINT UQ_System_SystemId UNIQUE (SystemId), + CONSTRAINT PKC_System PRIMARY KEY CLUSTERED (Value) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE [dbo].[TaskInfo] ( + [TaskId] VARCHAR (64) NOT NULL, + [QueueId] VARCHAR (64) NOT NULL, + [Status] SMALLINT NOT NULL, + [TaskTypeId] SMALLINT NOT NULL, + [RunId] VARCHAR (50) NULL, + [IsCanceled] BIT NOT NULL, + [RetryCount] SMALLINT NOT NULL, + [MaxRetryCount] SMALLINT NOT NULL, + [HeartbeatDateTime] DATETIME2 (7) NULL, + [InputData] VARCHAR (MAX) NOT NULL, + [TaskContext] VARCHAR (MAX) NULL, + [Result] VARCHAR (MAX) NULL, + [CreateDateTime] DATETIME2 (7) CONSTRAINT DF_TaskInfo_CreateDate DEFAULT SYSUTCDATETIME() NOT NULL, + [StartDateTime] DATETIME2 (7) NULL, + [EndDateTime] DATETIME2 (7) NULL, + [Worker] VARCHAR (100) NULL, + [RestartInfo] VARCHAR (MAX) NULL, + [ParentTaskId] VARCHAR (64) NULL, + CONSTRAINT PKC_TaskInfo PRIMARY KEY CLUSTERED (TaskId) WITH (DATA_COMPRESSION = PAGE) +) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; + + +GO +CREATE NONCLUSTERED INDEX IX_QueueId_Status + ON dbo.TaskInfo(QueueId, Status); + + +GO +CREATE NONCLUSTERED INDEX IX_QueueId_ParentTaskId + ON dbo.TaskInfo(QueueId, ParentTaskId); + +CREATE TABLE dbo.TokenDateTimeCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + StartDateTime2 DATETIME2 (7) NOT NULL, + EndDateTime2 DATETIME2 (7) NOT NULL, + IsLongerThanADay2 BIT NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenDateTimeCompositeSearchParam + ADD CONSTRAINT CHK_TokenDateTimeCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenDateTimeCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenDateTimeCompositeSearchParam + ON dbo.TokenDateTimeCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_StartDateTime2_EndDateTime2_INCLUDE_SystemId1_IsLongerThanADay2 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, StartDateTime2, EndDateTime2) + INCLUDE(SystemId1, IsLongerThanADay2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_EndDateTime2_StartDateTime2_INCLUDE_SystemId1_IsLongerThanADay2 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, EndDateTime2, StartDateTime2) + INCLUDE(SystemId1, IsLongerThanADay2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_StartDateTime2_EndDateTime2_INCLUDE_SystemId1_WHERE_IsLongerThanADay2_1 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, StartDateTime2, EndDateTime2) + INCLUDE(SystemId1) WHERE IsLongerThanADay2 = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_EndDateTime2_StartDateTime2_INCLUDE_SystemId1_WHERE_IsLongerThanADay2_1 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, EndDateTime2, StartDateTime2) + INCLUDE(SystemId1) WHERE IsLongerThanADay2 = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenNumberNumberCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + SingleValue3 DECIMAL (36, 18) NULL, + LowValue3 DECIMAL (36, 18) NULL, + HighValue3 DECIMAL (36, 18) NULL, + HasRange BIT NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenNumberNumberCompositeSearchParam + ADD CONSTRAINT CHK_TokenNumberNumberCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenNumberNumberCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenNumberNumberCompositeSearchParam + ON dbo.TokenNumberNumberCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_SingleValue2_SingleValue3_INCLUDE_SystemId1_WHERE_HasRange_0 + ON dbo.TokenNumberNumberCompositeSearchParam(SearchParamId, Code1, SingleValue2, SingleValue3) + INCLUDE(SystemId1) WHERE HasRange = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_LowValue2_HighValue2_LowValue3_HighValue3_INCLUDE_SystemId1_WHERE_HasRange_1 + ON dbo.TokenNumberNumberCompositeSearchParam(SearchParamId, Code1, LowValue2, HighValue2, LowValue3, HighValue3) + INCLUDE(SystemId1) WHERE HasRange = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenQuantityCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SystemId2 INT NULL, + QuantityCodeId2 INT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenQuantityCompositeSearchParam + ADD CONSTRAINT CHK_TokenQuantityCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenQuantityCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenQuantityCompositeSearchParam + ON dbo.TokenQuantityCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_SingleValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_SingleValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, SingleValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE SingleValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_LowValue2_HighValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_LowValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, LowValue2, HighValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE LowValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_HighValue2_LowValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_LowValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, HighValue2, LowValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE LowValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + Code VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenSearchParam + ADD CONSTRAINT CHK_TokenSearchParam_CodeOverflow CHECK (LEN(Code) = 256 + OR CodeOverflow IS NULL); + +ALTER TABLE dbo.TokenSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenSearchParam + ON dbo.TokenSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code_INCLUDE_SystemId + ON dbo.TokenSearchParam(SearchParamId, Code) + INCLUDE(SystemId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenStringCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + Text2 NVARCHAR (256) COLLATE Latin1_General_CI_AI NOT NULL, + TextOverflow2 NVARCHAR (MAX) COLLATE Latin1_General_CI_AI NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenStringCompositeSearchParam + ADD CONSTRAINT CHK_TokenStringCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenStringCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenStringCompositeSearchParam + ON dbo.TokenStringCompositeSearchParam(ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Text2_INCLUDE_SystemId1_TextOverflow2 + ON dbo.TokenStringCompositeSearchParam(SearchParamId, Code1, Text2) + INCLUDE(SystemId1, TextOverflow2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Text2_INCLUDE_SystemId1_WHERE_TextOverflow2_NOT_NULL + ON dbo.TokenStringCompositeSearchParam(SearchParamId, Code1, Text2) + INCLUDE(SystemId1) WHERE TextOverflow2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenText ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (400) COLLATE Latin1_General_CI_AI NOT NULL, + IsHistory BIT NOT NULL +); + +ALTER TABLE dbo.TokenText + ADD CONSTRAINT DF_TokenText_IsHistory DEFAULT 0 FOR IsHistory; + +ALTER TABLE dbo.TokenText SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenText + ON dbo.TokenText(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE NONCLUSTERED INDEX IX_TokenText_SearchParamId_Text + ON dbo.TokenText(ResourceTypeId, SearchParamId, Text, ResourceSurrogateId) WHERE IsHistory = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenTokenCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam + ADD CONSTRAINT CHK_TokenTokenCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam + ADD CONSTRAINT CHK_TokenTokenCompositeSearchParam_CodeOverflow2 CHECK (LEN(Code2) = 256 + OR CodeOverflow2 IS NULL); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenTokenCompositeSearchParam + ON dbo.TokenTokenCompositeSearchParam(ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Code2_INCLUDE_SystemId1_SystemId2 + ON dbo.TokenTokenCompositeSearchParam(SearchParamId, Code1, Code2) + INCLUDE(SystemId1, SystemId2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.Transactions ( + SurrogateIdRangeFirstValue BIGINT NOT NULL, + SurrogateIdRangeLastValue BIGINT NOT NULL, + Definition VARCHAR (2000) NULL, + IsCompleted BIT CONSTRAINT DF_Transactions_IsCompleted DEFAULT 0 NOT NULL, + IsSuccess BIT CONSTRAINT DF_Transactions_IsSuccess DEFAULT 0 NOT NULL, + IsVisible BIT CONSTRAINT DF_Transactions_IsVisible DEFAULT 0 NOT NULL, + IsHistoryMoved BIT CONSTRAINT DF_Transactions_IsHistoryMoved DEFAULT 0 NOT NULL, + CreateDate DATETIME CONSTRAINT DF_Transactions_CreateDate DEFAULT getUTCdate() NOT NULL, + EndDate DATETIME NULL, + VisibleDate DATETIME NULL, + HistoryMovedDate DATETIME NULL, + HeartbeatDate DATETIME CONSTRAINT DF_Transactions_HeartbeatDate DEFAULT getUTCdate() NOT NULL, + FailureReason VARCHAR (MAX) NULL, + IsControlledByClient BIT CONSTRAINT DF_Transactions_IsControlledByClient DEFAULT 1 NOT NULL, + InvisibleHistoryRemovedDate DATETIME NULL CONSTRAINT PKC_Transactions_SurrogateIdRangeFirstValue PRIMARY KEY CLUSTERED (SurrogateIdRangeFirstValue) +); + +CREATE INDEX IX_IsVisible + ON dbo.Transactions(IsVisible); + +CREATE TABLE dbo.UriSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL +); + +ALTER TABLE dbo.UriSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_UriSearchParam + ON dbo.UriSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Uri + ON dbo.UriSearchParam(SearchParamId, Uri) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.WatchdogLeases ( + Watchdog VARCHAR (100) NOT NULL, + LeaseHolder VARCHAR (100) CONSTRAINT DF_WatchdogLeases_LeaseHolder DEFAULT '' NOT NULL, + LeaseEndTime DATETIME CONSTRAINT DF_WatchdogLeases_LeaseEndTime DEFAULT 0 NOT NULL, + RemainingLeaseTimeSec AS datediff(second, getUTCdate(), LeaseEndTime), + LeaseRequestor VARCHAR (100) CONSTRAINT DF_WatchdogLeases_LeaseRequestor DEFAULT '' NOT NULL, + LeaseRequestTime DATETIME CONSTRAINT DF_WatchdogLeases_LeaseRequestTime DEFAULT 0 NOT NULL CONSTRAINT PKC_WatchdogLeases_Watchdog PRIMARY KEY CLUSTERED (Watchdog) +); + +COMMIT +GO +CREATE PROCEDURE dbo.AcquireReindexJobs +@jobHeartbeatTimeoutThresholdInSeconds BIGINT, @maximumNumberOfConcurrentJobsAllowed INT +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; +BEGIN TRANSACTION; +DECLARE @expirationDateTime AS DATETIME2 (7); +SELECT @expirationDateTime = DATEADD(second, -@jobHeartbeatTimeoutThresholdInSeconds, SYSUTCDATETIME()); +DECLARE @numberOfRunningJobs AS INT; +SELECT @numberOfRunningJobs = COUNT(*) +FROM dbo.ReindexJob WITH (TABLOCKX) +WHERE Status = 'Running' + AND HeartbeatDateTime > @expirationDateTime; +DECLARE @limit AS INT = @maximumNumberOfConcurrentJobsAllowed - @numberOfRunningJobs; +IF (@limit > 0) + BEGIN + DECLARE @availableJobs TABLE ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + JobVersion BINARY (8) NOT NULL); + INSERT INTO @availableJobs + SELECT TOP (@limit) Id, + JobVersion + FROM dbo.ReindexJob + WHERE (Status = 'Queued' + OR (Status = 'Running' + AND HeartbeatDateTime <= @expirationDateTime)) + ORDER BY HeartbeatDateTime; + DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); + UPDATE dbo.ReindexJob + SET Status = 'Running', + HeartbeatDateTime = @heartbeatDateTime, + RawJobRecord = JSON_MODIFY(RawJobRecord, '$.status', 'Running') + OUTPUT inserted.RawJobRecord, inserted.JobVersion + FROM dbo.ReindexJob AS job + INNER JOIN + @availableJobs AS availableJob + ON job.Id = availableJob.Id + AND job.JobVersion = availableJob.JobVersion; + END +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.AcquireWatchdogLease +@Watchdog VARCHAR (100), @Worker VARCHAR (100), @AllowRebalance BIT=1, @ForceAcquire BIT=0, @LeasePeriodSec FLOAT, @WorkerIsRunning BIT=0, @LeaseEndTime DATETIME OUTPUT, @IsAcquired BIT OUTPUT, @CurrentLeaseHolder VARCHAR (100)=NULL OUTPUT +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +DECLARE @SP AS VARCHAR (100) = 'AcquireWatchdogLease', @Mode AS VARCHAR (100), @msg AS VARCHAR (1000), @MyLeasesNumber AS INT, @OtherValidRequestsOrLeasesNumber AS INT, @MyValidRequestsOrLeasesNumber AS INT, @DesiredLeasesNumber AS INT, @NotLeasedWatchdogNumber AS INT, @WatchdogNumber AS INT, @Now AS DATETIME, @MyLastChangeTime AS DATETIME, @PreviousLeaseHolder AS VARCHAR (100), @Rows AS INT = 0, @NumberOfWorkers AS INT, @st AS DATETIME = getUTCdate(), @RowsInt AS INT, @Pattern AS VARCHAR (100); +BEGIN TRY + SET @Mode = 'R=' + isnull(@Watchdog, 'NULL') + ' W=' + isnull(@Worker, 'NULL') + ' F=' + isnull(CONVERT (VARCHAR, @ForceAcquire), 'NULL') + ' LP=' + isnull(CONVERT (VARCHAR, @LeasePeriodSec), 'NULL'); + SET @CurrentLeaseHolder = ''; + SET @IsAcquired = 0; + SET @Now = getUTCdate(); + SET @LeaseEndTime = @Now; + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderIncludePatternFor' + @Watchdog), ''); + IF @Pattern IS NULL + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderIncludePattern'), ''); + IF @Pattern IS NOT NULL + AND @Worker NOT LIKE @Pattern + BEGIN + SET @msg = 'Worker does not match include pattern=' + @Pattern; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; + SET @CurrentLeaseHolder = isnull((SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog), ''); + RETURN; + END + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderExcludePatternFor' + @Watchdog), ''); + IF @Pattern IS NULL + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderExcludePattern'), ''); + IF @Pattern IS NOT NULL + AND @Worker LIKE @Pattern + BEGIN + SET @msg = 'Worker matches exclude pattern=' + @Pattern; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; + SET @CurrentLeaseHolder = isnull((SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog), ''); + RETURN; + END + DECLARE @Watchdogs TABLE ( + Watchdog VARCHAR (100) PRIMARY KEY); + INSERT INTO @Watchdogs + SELECT Watchdog + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE RemainingLeaseTimeSec * (-1) > 10 * @LeasePeriodSec + OR @ForceAcquire = 1 + AND Watchdog = @Watchdog + AND LeaseHolder <> @Worker; + IF @@rowcount > 0 + BEGIN + DELETE dbo.WatchdogLeases + WHERE Watchdog IN (SELECT Watchdog + FROM @Watchdogs); + SET @Rows += @@rowcount; + IF @Rows > 0 + BEGIN + SET @msg = ''; + SELECT @msg = CONVERT (VARCHAR (1000), @msg + CASE WHEN @msg = '' THEN '' ELSE ',' END + Watchdog) + FROM @Watchdogs; + SET @msg = CONVERT (VARCHAR (1000), 'Remove old/forced leases:' + @msg); + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Target = 'WatchdogLeases', @Action = 'Delete', @Rows = @Rows, @Text = @msg; + END + END + SET @NumberOfWorkers = 1 + (SELECT count(*) + FROM (SELECT LeaseHolder + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder <> @Worker + UNION + SELECT LeaseRequestor + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseRequestor <> @Worker + AND LeaseRequestor <> '') AS A); + SET @Mode = CONVERT (VARCHAR (100), @Mode + ' N=' + CONVERT (VARCHAR (10), @NumberOfWorkers)); + IF NOT EXISTS (SELECT * + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE Watchdog = @Watchdog) + INSERT INTO dbo.WatchdogLeases (Watchdog, LeaseEndTime, LeaseRequestTime) + SELECT @Watchdog, + dateadd(day, -10, @Now), + dateadd(day, -10, @Now) + WHERE NOT EXISTS (SELECT * + FROM dbo.WatchdogLeases WITH (TABLOCKX) + WHERE Watchdog = @Watchdog); + SET @LeaseEndTime = dateadd(second, @LeasePeriodSec, @Now); + SET @WatchdogNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK)); + SET @NotLeasedWatchdogNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = '' + OR LeaseEndTime < @Now); + SET @MyLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = @Worker + AND LeaseEndTime > @Now); + SET @OtherValidRequestsOrLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder <> @Worker + AND LeaseEndTime > @Now + OR LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec); + SET @MyValidRequestsOrLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = @Worker + AND LeaseEndTime > @Now + OR LeaseRequestor = @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec); + SET @DesiredLeasesNumber = ceiling(1.0 * @WatchdogNumber / @NumberOfWorkers); + IF @DesiredLeasesNumber = 0 + SET @DesiredLeasesNumber = 1; + IF @DesiredLeasesNumber = 1 + AND @OtherValidRequestsOrLeasesNumber = 1 + AND @WatchdogNumber = 1 + SET @DesiredLeasesNumber = 0; + IF @MyValidRequestsOrLeasesNumber = floor(1.0 * @WatchdogNumber / @NumberOfWorkers) + AND @OtherValidRequestsOrLeasesNumber + @MyValidRequestsOrLeasesNumber = @WatchdogNumber + SET @DesiredLeasesNumber = @DesiredLeasesNumber - 1; + UPDATE dbo.WatchdogLeases + SET LeaseHolder = @Worker, + LeaseEndTime = @LeaseEndTime, + LeaseRequestor = '', + @PreviousLeaseHolder = LeaseHolder + WHERE Watchdog = @Watchdog + AND NOT (LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec) + AND (LeaseHolder = @Worker + AND (LeaseEndTime > @Now + OR @WorkerIsRunning = 1) + OR LeaseEndTime < @Now + AND (@DesiredLeasesNumber > @MyLeasesNumber + OR @OtherValidRequestsOrLeasesNumber < @WatchdogNumber)); + IF @@rowcount > 0 + BEGIN + SET @IsAcquired = 1; + SET @msg = 'Lease holder changed from [' + isnull(@PreviousLeaseHolder, '') + '] to [' + @Worker + ']'; + IF @PreviousLeaseHolder <> @Worker + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Text = @msg; + END + ELSE + IF @AllowRebalance = 1 + BEGIN + SET @CurrentLeaseHolder = (SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog); + UPDATE dbo.WatchdogLeases + SET LeaseRequestTime = @Now + WHERE Watchdog = @Watchdog + AND LeaseRequestor = @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec; + IF @DesiredLeasesNumber > @MyValidRequestsOrLeasesNumber + BEGIN + UPDATE A + SET LeaseRequestor = @Worker, + LeaseRequestTime = @Now + FROM dbo.WatchdogLeases AS A + WHERE Watchdog = @Watchdog + AND NOT (LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec) + AND @NotLeasedWatchdogNumber = 0 + AND (SELECT count(*) + FROM dbo.WatchdogLeases AS B + WHERE B.LeaseHolder = A.LeaseHolder + AND datediff(second, B.LeaseEndTime, @Now) < @LeasePeriodSec) > @DesiredLeasesNumber; + SET @RowsInt = @@rowcount; + SET @msg = '@DesiredLeasesNumber=[' + CONVERT (VARCHAR (10), @DesiredLeasesNumber) + '] > @MyValidRequestsOrLeasesNumber=[' + CONVERT (VARCHAR (10), @MyValidRequestsOrLeasesNumber) + ']'; + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Rows = @RowsInt, @Text = @msg; + END + END + SET @Mode = CONVERT (VARCHAR (100), @Mode + ' A=' + CONVERT (VARCHAR (1), @IsAcquired)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Error', @Mode = @Mode; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.AddPartitionOnResourceChanges +@partitionBoundary DATETIME2 (7) OUTPUT +AS +BEGIN + SET XACT_ABORT ON; + BEGIN TRANSACTION; + DECLARE @rightPartitionBoundary AS DATETIME2 (7) = CAST ((SELECT TOP (1) value + FROM sys.partition_range_values AS prv + INNER JOIN + sys.partition_functions AS pf + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + ORDER BY prv.boundary_id DESC) AS DATETIME2 (7)); + DECLARE @timestamp AS DATETIME2 (7) = DATEADD(hour, DATEDIFF(hour, 0, sysutcdatetime()), 0); + IF (@rightPartitionBoundary < @timestamp) + BEGIN + SET @rightPartitionBoundary = @timestamp; + END + SET @rightPartitionBoundary = DATEADD(hour, 1, @rightPartitionBoundary); + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [Primary]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@rightPartitionBoundary); + SET @partitionBoundary = @rightPartitionBoundary; + COMMIT TRANSACTION; +END + +GO +CREATE PROCEDURE dbo.ArchiveJobs +@QueueType TINYINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'ArchiveJobs', @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0, @InflightRows AS INT = 0, @Lock AS VARCHAR (100) = 'DequeueJob_' + CONVERT (VARCHAR, @QueueType); +BEGIN TRY + SET @PartitionId = @MaxPartitions * rand(); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + WHILE @LookedAtPartitions <= @MaxPartitions + BEGIN + SET @InflightRows += (SELECT count(*) + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (0, 1)); + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + IF @InflightRows = 0 + BEGIN + SET @LookedAtPartitions = 0; + WHILE @LookedAtPartitions <= @MaxPartitions + BEGIN + UPDATE dbo.JobQueue + SET Status = 5 + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (2, 3, 4); + SET @Rows += @@rowcount; + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.CaptureResourceChanges +@isDeleted BIT, @version INT, @resourceId VARCHAR (64), @resourceTypeId SMALLINT +AS +BEGIN + DECLARE @changeType AS SMALLINT; + IF (@isDeleted = 1) + BEGIN + SET @changeType = 2; + END + ELSE + BEGIN + IF (@version = 1) + BEGIN + SET @changeType = 0; + END + ELSE + BEGIN + SET @changeType = 1; + END + END + INSERT INTO dbo.ResourceChangeData (ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId) + VALUES (@resourceId, @resourceTypeId, @version, @changeType); +END + +GO +CREATE PROCEDURE dbo.CaptureResourceIdsForChanges +@Resources dbo.ResourceList READONLY +AS +SET NOCOUNT ON; +INSERT INTO dbo.ResourceChangeData (ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId) +SELECT ResourceId, + ResourceTypeId, + Version, + CASE WHEN IsDeleted = 1 THEN 2 WHEN Version > 1 THEN 1 ELSE 0 END +FROM @Resources +WHERE IsHistory = 0; + +GO +CREATE PROCEDURE dbo.CheckActiveReindexJobs +AS +SET NOCOUNT ON; +SELECT Id +FROM dbo.ReindexJob +WHERE Status = 'Running' + OR Status = 'Queued' + OR Status = 'Paused'; + +GO +CREATE PROCEDURE dbo.CleanupEventLog +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'CleanupEventLog', @Mode AS VARCHAR (100) = '', @MaxDeleteRows AS INT, @MaxAllowedRows AS BIGINT, @RetentionPeriodSecond AS INT, @DeletedRows AS INT, @TotalDeletedRows AS INT = 0, @TotalRows AS INT, @Now AS DATETIME = getUTCdate(); +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; +BEGIN TRY + SET @MaxDeleteRows = (SELECT Number + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.DeleteBatchSize'); + IF @MaxDeleteRows IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.DeleteBatchSize', 18, 127); + SET @MaxAllowedRows = (SELECT Number + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.AllowedRows'); + IF @MaxAllowedRows IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.AllowedRows', 18, 127); + SET @RetentionPeriodSecond = (SELECT Number * 24 * 60 * 60 + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.RetentionPeriodDay'); + IF @RetentionPeriodSecond IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.RetentionPeriodDay', 18, 127); + SET @TotalRows = (SELECT sum(row_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id('EventLog') + AND index_id IN (0, 1)); + SET @DeletedRows = 1; + WHILE @DeletedRows > 0 + AND EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.IsEnabled' + AND Number = 1) + BEGIN + SET @DeletedRows = 0; + IF @TotalRows - @TotalDeletedRows > @MaxAllowedRows + BEGIN + DELETE TOP (@MaxDeleteRows) + dbo.EventLog WITH (PAGLOCK) + WHERE EventDate <= dateadd(second, -@RetentionPeriodSecond, @Now); + SET @DeletedRows = @@rowcount; + SET @TotalDeletedRows += @DeletedRows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'EventLog', @Action = 'Delete', @Rows = @DeletedRows, @Text = @TotalDeletedRows; + END + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @Now; +END TRY +BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.ConfigurePartitionOnResourceChanges +@numberOfFuturePartitionsToAdd INT +AS +BEGIN + SET XACT_ABORT ON; + BEGIN TRANSACTION; + DECLARE @partitionBoundary AS DATETIME2 (7) = DATEADD(hour, DATEDIFF(hour, 0, sysutcdatetime()), 0); + DECLARE @startingRightPartitionBoundary AS DATETIME2 (7) = CAST ((SELECT TOP (1) value + FROM sys.partition_range_values AS prv + INNER JOIN + sys.partition_functions AS pf + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + ORDER BY prv.boundary_id DESC) AS DATETIME2 (7)); + DECLARE @numberOfPartitionsToAdd AS INT = @numberOfFuturePartitionsToAdd + 1; + WHILE @numberOfPartitionsToAdd > 0 + BEGIN + IF (@startingRightPartitionBoundary < @partitionBoundary) + BEGIN + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [PRIMARY]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@partitionBoundary); + END + SET @partitionBoundary = DATEADD(hour, 1, @partitionBoundary); + SET @numberOfPartitionsToAdd -= 1; + END + COMMIT TRANSACTION; +END + +GO +CREATE PROCEDURE dbo.CreateReindexJob +@id VARCHAR (64), @status VARCHAR (10), @rawJobRecord VARCHAR (MAX) +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +BEGIN TRANSACTION; +DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); +INSERT INTO dbo.ReindexJob (Id, Status, HeartbeatDateTime, RawJobRecord) +VALUES (@id, @status, @heartbeatDateTime, @rawJobRecord); +SELECT CAST (MIN_ACTIVE_ROWVERSION() AS INT); +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.CreateResourceSearchParamStats +@Table VARCHAR (100), @Column VARCHAR (100), @ResourceTypeId SMALLINT, @SearchParamId SMALLINT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'T=' + isnull(@Table, 'NULL') + ' C=' + isnull(@Column, 'NULL') + ' RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' SP=' + isnull(CONVERT (VARCHAR, @SearchParamId), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + IF @Table IS NULL + OR @Column IS NULL + OR @ResourceTypeId IS NULL + OR @SearchParamId IS NULL + RAISERROR ('@TableName IS NULL OR @KeyColumn IS NULL OR @ResourceTypeId IS NULL OR @SearchParamId IS NULL', 18, 127); + EXECUTE ('CREATE STATISTICS ST_' + @Column + '_WHERE_ResourceTypeId_' + @ResourceTypeId + '_SearchParamId_' + @SearchParamId + ' ON dbo.' + @Table + ' (' + @Column + ') WHERE ResourceTypeId = ' + @ResourceTypeId + ' AND SearchParamId = ' + @SearchParamId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = 'Stats created'; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF error_number() = 1927 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; + RETURN; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.Defrag +@TableName VARCHAR (100), @IndexName VARCHAR (200), @PartitionNumber INT, @IsPartitioned BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = @TableName + '.' + @IndexName + '.' + CONVERT (VARCHAR, @PartitionNumber) + '.' + CONVERT (VARCHAR, @IsPartitioned), @st AS DATETIME = getUTCdate(), @SQL AS VARCHAR (3500), @msg AS VARCHAR (1000), @SizeBefore AS FLOAT, @SizeAfter AS FLOAT, @IndexId AS INT, @Operation AS VARCHAR (50) = CASE WHEN EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'Defrag.IndexRebuild.IsEnabled' + AND Number = 1) THEN 'REBUILD' ELSE 'REORGANIZE' END; +SET @Mode = @Mode + ' ' + @Operation; +BEGIN TRY + SET @IndexId = (SELECT index_id + FROM sys.indexes + WHERE object_id = object_id(@TableName) + AND name = @IndexName); + SET @Sql = 'ALTER INDEX ' + quotename(@IndexName) + ' ON dbo.' + quotename(@TableName) + ' ' + @Operation + CASE WHEN @IsPartitioned = 1 THEN ' PARTITION = ' + CONVERT (VARCHAR, @PartitionNumber) ELSE '' END + CASE WHEN @Operation = 'REBUILD' THEN ' WITH (ONLINE = ON ' + CASE WHEN EXISTS (SELECT * + FROM sys.partitions + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId + AND data_compression_desc = 'PAGE') THEN ', DATA_COMPRESSION = PAGE' ELSE ')' END ELSE '' END; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start', @Text = @Sql; + SET @SizeBefore = (SELECT sum(reserved_page_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId) * 8.0 / 1024 / 1024; + SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Text = @msg; + BEGIN TRY + EXECUTE (@Sql); + SET @SizeAfter = (SELECT sum(reserved_page_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId) * 8.0 / 1024 / 1024; + SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore) + ', after=' + CONVERT (VARCHAR, @SizeAfter) + ', reduced by=' + CONVERT (VARCHAR, @SizeBefore - @SizeAfter); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'End', @Mode = @Mode, @Action = @Operation, @Start = @st, @Text = @msg; + END TRY + BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Error', @Mode = @Mode, @Action = @Operation, @Start = @st; + THROW; + END CATCH +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DefragChangeDatabaseSettings +@IsOn BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DefragChangeDatabaseSettings', @Mode AS VARCHAR (200) = 'On=' + CONVERT (VARCHAR, @IsOn), @st AS DATETIME = getUTCdate(), @SQL AS VARCHAR (3500); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Start', @Mode = @Mode; + SET @SQL = 'ALTER DATABASE CURRENT SET AUTO_UPDATE_STATISTICS ' + CASE WHEN @IsOn = 1 THEN 'ON' ELSE 'OFF' END; + EXECUTE (@SQL); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Run', @Mode = @Mode, @Text = @SQL; + SET @SQL = 'ALTER DATABASE CURRENT SET AUTO_CREATE_STATISTICS ' + CASE WHEN @IsOn = 1 THEN 'ON' ELSE 'OFF' END; + EXECUTE (@SQL); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'End', @Mode = @Mode, @Start = @st, @Text = @SQL; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DefragGetFragmentation +@TableName VARCHAR (200), @IndexName VARCHAR (200)=NULL, @PartitionNumber INT=NULL +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @st AS DATETIME = getUTCdate(), @msg AS VARCHAR (1000), @Rows AS INT, @MinFragPct AS INT = isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'Defrag.MinFragPct'), 10), @MinSizeGB AS FLOAT = isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'Defrag.MinSizeGB'), 0.1), @PreviousGroupId AS BIGINT, @IndexId AS INT; +DECLARE @Mode AS VARCHAR (200) = 'T=' + @TableName + ' I=' + isnull(@IndexName, 'NULL') + ' P=' + CONVERT (VARCHAR, @PartitionNumber) + ' MF=' + CONVERT (VARCHAR, @MinFragPct) + ' MS=' + CONVERT (VARCHAR, @MinSizeGB); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF object_id(@TableName) IS NULL + RAISERROR ('Table does not exist', 18, 127); + SET @IndexId = (SELECT index_id + FROM sys.indexes + WHERE object_id = object_id(@TableName) + AND name = @IndexName); + IF @IndexName IS NOT NULL + AND @IndexId IS NULL + RAISERROR ('Index does not exist', 18, 127); + SET @PreviousGroupId = (SELECT TOP 1 GroupId + FROM dbo.JobQueue + WHERE QueueType = 3 + AND Status = 5 + AND Definition = @TableName + ORDER BY GroupId DESC); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@PreviousGroupId', @Text = @PreviousGroupId; + SELECT TableName, + IndexName, + partition_number, + frag_in_percent + FROM (SELECT @TableName AS TableName, + I.name AS IndexName, + partition_number, + avg_fragmentation_in_percent AS frag_in_percent, + isnull(CONVERT (FLOAT, Result), 0) AS prev_frag_in_percent + FROM (SELECT object_id, + index_id, + partition_number, + avg_fragmentation_in_percent + FROM sys.dm_db_index_physical_stats(db_id(), object_id(@TableName), @IndexId, @PartitionNumber, 'LIMITED') AS A + WHERE index_id > 0 + AND (@PartitionNumber IS NOT NULL + OR avg_fragmentation_in_percent >= @MinFragPct + AND A.page_count > @MinSizeGB * 1024 * 1024 / 8)) AS A + INNER JOIN + sys.indexes AS I + ON I.object_id = A.object_id + AND I.index_id = A.index_id + LEFT OUTER JOIN + dbo.JobQueue + ON QueueType = 3 + AND Status = 5 + AND GroupId = @PreviousGroupId + AND Definition = I.name + ';' + CONVERT (VARCHAR, partition_number)) AS A + WHERE @PartitionNumber IS NOT NULL + OR frag_in_percent >= prev_frag_in_percent + @MinFragPct; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DeleteHistory +@DeleteResources BIT=0, @Reset BIT=0, @DisableLogEvent BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DeleteHistory', @Mode AS VARCHAR (100) = 'D=' + isnull(CONVERT (VARCHAR, @DeleteResources), 'NULL') + ' R=' + isnull(CONVERT (VARCHAR, @Reset), 'NULL'), @st AS DATETIME = getUTCdate(), @Id AS VARCHAR (100) = 'DeleteHistory.LastProcessed.TypeId.SurrogateId', @ResourceTypeId AS SMALLINT, @SurrogateId AS BIGINT, @RowsToProcess AS INT, @ProcessedResources AS INT = 0, @DeletedResources AS INT = 0, @DeletedSearchParams AS INT = 0, @ReportDate AS DATETIME = getUTCdate(); +BEGIN TRY + IF @DisableLogEvent = 0 + INSERT INTO dbo.Parameters (Id, Char) + SELECT @SP, + 'LogEvent'; + ELSE + DELETE dbo.Parameters + WHERE Id = @SP; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + INSERT INTO dbo.Parameters (Id, Char) + SELECT @Id, + '0.0' + WHERE NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = @Id); + DECLARE @LastProcessed AS VARCHAR (100) = CASE WHEN @Reset = 0 THEN (SELECT Char + FROM dbo.Parameters + WHERE Id = @Id) ELSE '0.0' END; + DECLARE @Types TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + DECLARE @SurrogateIds TABLE ( + ResourceSurrogateId BIGINT PRIMARY KEY, + IsHistory BIT ); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Insert', @Rows = @@rowcount; + SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1); + SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255); + DELETE @Types + WHERE ResourceTypeId < @ResourceTypeId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Delete', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @Types + ORDER BY ResourceTypeId); + SET @ProcessedResources = 0; + SET @DeletedResources = 0; + SET @DeletedSearchParams = 0; + SET @RowsToProcess = 1; + WHILE @RowsToProcess > 0 + BEGIN + DELETE @SurrogateIds; + INSERT INTO @SurrogateIds + SELECT TOP 10000 ResourceSurrogateId, + IsHistory + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId + ORDER BY ResourceSurrogateId; + SET @RowsToProcess = @@rowcount; + SET @ProcessedResources += @RowsToProcess; + IF @RowsToProcess > 0 + SET @SurrogateId = (SELECT max(ResourceSurrogateId) + FROM @SurrogateIds); + SET @LastProcessed = CONVERT (VARCHAR, @ResourceTypeId) + '.' + CONVERT (VARCHAR, @SurrogateId); + DELETE @SurrogateIds + WHERE IsHistory = 0; + IF EXISTS (SELECT * + FROM @SurrogateIds) + BEGIN + DELETE dbo.ResourceWriteClaim + WHERE ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.CompartmentAssignment + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.ReferenceSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenText + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.StringSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.UriSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.NumberSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.QuantitySearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.DateTimeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.ReferenceTokenCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenTokenCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenDateTimeCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenQuantityCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenStringCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenNumberNumberCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + IF @DeleteResources = 1 + BEGIN + DELETE dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedResources += @@rowcount; + END + END + UPDATE dbo.Parameters + SET Char = @LastProcessed + WHERE Id = @Id; + IF datediff(second, @ReportDate, getUTCdate()) > 60 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Select', @Rows = @ProcessedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '*SearchParam', @Action = 'Delete', @Rows = @DeletedSearchParams, @Text = @LastProcessed; + IF @DeleteResources = 1 + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Rows = @DeletedResources, @Text = @LastProcessed; + SET @ReportDate = getUTCdate(); + SET @ProcessedResources = 0; + SET @DeletedSearchParams = 0; + SET @DeletedResources = 0; + END + END + DELETE @Types + WHERE ResourceTypeId = @ResourceTypeId; + SET @SurrogateId = 0; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Select', @Rows = @ProcessedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '*SearchParam', @Action = 'Delete', @Rows = @DeletedSearchParams, @Text = @LastProcessed; + IF @DeleteResources = 1 + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Rows = @DeletedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DequeueJob +@QueueType TINYINT, @Worker VARCHAR (100), @HeartbeatTimeoutSec INT, @InputJobId BIGINT=NULL, @CheckTimeoutJobs BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DequeueJob', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' H=' + isnull(CONVERT (VARCHAR, @HeartbeatTimeoutSec), 'NULL') + ' W=' + isnull(@Worker, 'NULL') + ' IJ=' + isnull(CONVERT (VARCHAR, @InputJobId), 'NULL') + ' T=' + isnull(CONVERT (VARCHAR, @CheckTimeoutJobs), 'NULL'), @Rows AS INT = 0, @st AS DATETIME = getUTCdate(), @JobId AS BIGINT, @msg AS VARCHAR (100), @Lock AS VARCHAR (100), @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0; +BEGIN TRY + IF EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'DequeueJobStop' + AND Number = 1) + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = 0, @Text = 'Skipped'; + RETURN; + END + IF @InputJobId IS NULL + SET @PartitionId = @MaxPartitions * rand(); + ELSE + SET @PartitionId = @InputJobId % 16; + SET TRANSACTION ISOLATION LEVEL READ COMMITTED; + WHILE @InputJobId IS NULL + AND @JobId IS NULL + AND @LookedAtPartitions < @MaxPartitions + AND @CheckTimeoutJobs = 0 + BEGIN + SET @Lock = 'DequeueJob_' + CONVERT (VARCHAR, @QueueType) + '_' + CONVERT (VARCHAR, @PartitionId); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + UPDATE T + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = T.JobId + FROM dbo.JobQueue AS T WITH (PAGLOCK) + INNER JOIN + (SELECT TOP 1 JobId + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_PartitionId_Status_Priority)) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 0 + ORDER BY Priority, JobId) AS S + ON QueueType = @QueueType + AND PartitionId = @PartitionId + AND T.JobId = S.JobId; + SET @Rows += @@rowcount; + COMMIT TRANSACTION; + IF @JobId IS NULL + BEGIN + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + SET @LookedAtPartitions = 0; + WHILE @InputJobId IS NULL + AND @JobId IS NULL + AND @LookedAtPartitions < @MaxPartitions + BEGIN + SET @Lock = 'DequeueStoreCopyWorkUnit_' + CONVERT (VARCHAR, @PartitionId); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + UPDATE T + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = CASE WHEN CancelRequested = 0 THEN 1 ELSE 4 END, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = CASE WHEN CancelRequested = 0 THEN T.JobId END, + Info = CONVERT (VARCHAR (1000), isnull(Info, '') + ' Prev: Worker=' + Worker + ' Start=' + CONVERT (VARCHAR, StartDate, 121)) + FROM dbo.JobQueue AS T WITH (PAGLOCK) + INNER JOIN + (SELECT TOP 1 JobId + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_PartitionId_Status_Priority)) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 1 + AND datediff(second, HeartbeatDate, getUTCdate()) > @HeartbeatTimeoutSec + ORDER BY Priority, JobId) AS S + ON QueueType = @QueueType + AND PartitionId = @PartitionId + AND T.JobId = S.JobId; + SET @Rows += @@rowcount; + COMMIT TRANSACTION; + IF @JobId IS NULL + BEGIN + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + IF @InputJobId IS NOT NULL + BEGIN + UPDATE dbo.JobQueue WITH (PAGLOCK) + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = JobId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 0 + AND JobId = @InputJobId; + SET @Rows += @@rowcount; + IF @JobId IS NULL + BEGIN + UPDATE dbo.JobQueue WITH (PAGLOCK) + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = JobId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 1 + AND JobId = @InputJobId + AND datediff(second, HeartbeatDate, getUTCdate()) > @HeartbeatTimeoutSec; + SET @Rows += @@rowcount; + END + END + IF @JobId IS NOT NULL + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobId = @JobId; + SET @msg = 'J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL') + ' P=' + CONVERT (VARCHAR, @PartitionId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DisableIndex +@tableName NVARCHAR (128), @indexName NVARCHAR (128) +WITH EXECUTE AS 'dbo' +AS +DECLARE @errorTxt AS VARCHAR (1000), @sql AS NVARCHAR (1000), @isDisabled AS BIT; +IF object_id(@tableName) IS NULL + BEGIN + SET @errorTxt = @tableName + ' does not exist or you don''t have permissions.'; + RAISERROR (@errorTxt, 18, 127); + END +SET @isDisabled = (SELECT is_disabled + FROM sys.indexes + WHERE object_id = object_id(@tableName) + AND name = @indexName); +IF @isDisabled IS NULL + BEGIN + SET @errorTxt = @indexName + ' does not exist or you don''t have permissions.'; + RAISERROR (@errorTxt, 18, 127); + END +IF @isDisabled = 0 + BEGIN + SET @sql = N'ALTER INDEX ' + QUOTENAME(@indexName) + N' on ' + @tableName + ' Disable'; + EXECUTE sp_executesql @sql; + END + +GO +CREATE PROCEDURE dbo.DisableIndexes +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DisableIndexes', @Mode AS VARCHAR (200) = '', @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100), @Ind AS VARCHAR (200), @Txt AS VARCHAR (4000); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + Tbl VARCHAR (100) PRIMARY KEY, + Supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + DECLARE @Indexes TABLE ( + Tbl VARCHAR (100), + Ind VARCHAR (200), + TblId INT , + IndId INT PRIMARY KEY (Tbl, Ind)); + INSERT INTO @Indexes + SELECT Tbl, + I.Name, + TblId, + I.index_id + FROM (SELECT object_id(Tbl) AS TblId, + Tbl + FROM @Tables) AS O + INNER JOIN + sys.indexes AS I + ON I.object_id = TblId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + INSERT INTO dbo.IndexProperties (TableName, IndexName, PropertyName, PropertyValue) + SELECT Tbl, + Ind, + 'DATA_COMPRESSION', + data_comp + FROM (SELECT Tbl, + Ind, + isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions + WHERE object_id = TblId + AND index_id = IndId), 'NONE') AS data_comp + FROM @Indexes) AS A + WHERE NOT EXISTS (SELECT * + FROM dbo.IndexProperties + WHERE TableName = Tbl + AND IndexName = Ind); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'IndexProperties', @Action = 'Insert', @Rows = @@rowcount; + DELETE @Indexes + WHERE Tbl IN ('Resource', 'ResourceCurrent', 'ResourceHistory') + OR IndId = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Delete', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @Tbl = Tbl, + @Ind = Ind + FROM @Indexes; + SET @Txt = 'ALTER INDEX ' + @Ind + ' ON dbo.' + @Tbl + ' DISABLE'; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Ind, @Action = 'Disable', @Text = @Txt; + DELETE @Indexes + WHERE Tbl = @Tbl + AND Ind = @Ind; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.EnqueueJobs +@QueueType TINYINT, @Definitions StringList READONLY, @GroupId BIGINT=NULL, @ForceOneActiveJobGroup BIT=1, @IsCompleted BIT=NULL, @Status TINYINT=NULL, @Result VARCHAR (MAX)=NULL, @StartDate DATETIME=NULL, @ReturnJobs BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'EnqueueJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' D=' + CONVERT (VARCHAR, (SELECT count(*) + FROM @Definitions)) + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL') + ' F=' + isnull(CONVERT (VARCHAR, @ForceOneActiveJobGroup), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @Status), 'NULL'), @st AS DATETIME = getUTCdate(), @Lock AS VARCHAR (100) = 'EnqueueJobs_' + CONVERT (VARCHAR, @QueueType), @MaxJobId AS BIGINT, @Rows AS INT, @msg AS VARCHAR (1000), @JobIds AS BigintList, @InputRows AS INT; +BEGIN TRY + DECLARE @Input TABLE ( + DefinitionHash VARBINARY (20) PRIMARY KEY, + Definition VARCHAR (MAX) ); + INSERT INTO @Input + SELECT hashbytes('SHA1', String) AS DefinitionHash, + String AS Definition + FROM @Definitions; + SET @InputRows = @@rowcount; + INSERT INTO @JobIds + SELECT JobId + FROM @Input AS A + INNER JOIN + dbo.JobQueue AS B + ON B.QueueType = @QueueType + AND B.DefinitionHash = A.DefinitionHash + AND B.Status <> 5; + IF @@rowcount < @InputRows + BEGIN + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + IF @ForceOneActiveJobGroup = 1 + AND EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND Status IN (0, 1) + AND (@GroupId IS NULL + OR GroupId <> @GroupId)) + RAISERROR ('There are other active job groups', 18, 127); + SET @MaxJobId = isnull((SELECT TOP 1 JobId + FROM dbo.JobQueue + WHERE QueueType = @QueueType + ORDER BY JobId DESC), 0); + INSERT INTO dbo.JobQueue (QueueType, GroupId, JobId, Definition, DefinitionHash, Status, Result, StartDate) + OUTPUT inserted.JobId INTO @JobIds + SELECT @QueueType, + isnull(@GroupId, @MaxJobId + 1) AS GroupId, + JobId, + Definition, + DefinitionHash, + isnull(@Status, 0) AS Status, + CASE WHEN @Status = 2 THEN @Result ELSE NULL END AS Result, + CASE WHEN @Status = 1 THEN getUTCdate() ELSE @StartDate END AS StartDate + FROM (SELECT @MaxJobId + row_number() OVER (ORDER BY Dummy) AS JobId, + * + FROM (SELECT *, + 0 AS Dummy + FROM @Input) AS A) AS A + WHERE NOT EXISTS (SELECT * + FROM dbo.JobQueue AS B WITH (INDEX (IX_QueueType_DefinitionHash)) + WHERE B.QueueType = @QueueType + AND B.DefinitionHash = A.DefinitionHash + AND B.Status <> 5); + SET @Rows = @@rowcount; + COMMIT TRANSACTION; + END + IF @ReturnJobs = 1 + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.ExecuteCommandForRebuildIndexes +@Tbl VARCHAR (100), @Ind VARCHAR (1000), @Cmd VARCHAR (MAX) +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'ExecuteCommandForRebuildIndexes', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL'), @st AS DATETIME, @Retries AS INT = 0, @Action AS VARCHAR (100), @msg AS VARCHAR (1000); +RetryOnTempdbError: +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start', @Text = @Cmd; + SET @st = getUTCdate(); + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + IF @Cmd IS NULL + RAISERROR ('@Cmd IS NULL', 18, 127); + SET @Action = CASE WHEN @Cmd LIKE 'UPDATE STAT%' THEN 'Update statistics' WHEN @Cmd LIKE 'CREATE%INDEX%' THEN 'Create Index' WHEN @Cmd LIKE 'ALTER%INDEX%REBUILD%' THEN 'Rebuild Index' WHEN @Cmd LIKE 'ALTER%TABLE%ADD%' THEN 'Add Constraint' END; + IF @Action IS NULL + BEGIN + SET @msg = 'Not supported command = ' + CONVERT (VARCHAR (900), @Cmd); + RAISERROR (@msg, 18, 127); + END + IF @Action = 'Create Index' + WAITFOR DELAY '00:00:05'; + EXECUTE (@Cmd); + SELECT @Ind; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Action = @Action, @Status = 'End', @Start = @st, @Text = @Cmd; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF error_number() = 40544 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st, @Retry = @Retries; + SET @Retries = @Retries + 1; + IF @Tbl = 'TokenText_96' + WAITFOR DELAY '01:00:00'; + ELSE + WAITFOR DELAY '00:10:00'; + GOTO RetryOnTempdbError; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.FetchEventAgentCheckpoint +@CheckpointId VARCHAR (64) +AS +BEGIN + SELECT TOP (1) CheckpointId, + LastProcessedDateTime, + LastProcessedIdentifier + FROM dbo.EventAgentCheckpoint + WHERE CheckpointId = @CheckpointId; +END + +GO +CREATE PROCEDURE dbo.FetchResourceChanges_3 +@startId BIGINT, @lastProcessedUtcDateTime DATETIME2 (7), @pageSize SMALLINT +AS +BEGIN + SET NOCOUNT ON; + DECLARE @precedingPartitionBoundary AS DATETIME2 (7) = (SELECT TOP (1) CAST (prv.value AS DATETIME2 (7)) AS value + FROM sys.partition_range_values AS prv WITH (NOLOCK) + INNER JOIN + sys.partition_functions AS pf WITH (NOLOCK) + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + AND SQL_VARIANT_PROPERTY(prv.Value, 'BaseType') = 'datetime2' + AND CAST (prv.value AS DATETIME2 (7)) < DATEADD(HOUR, DATEDIFF(HOUR, 0, @lastProcessedUtcDateTime), 0) + ORDER BY prv.boundary_id DESC); + IF (@precedingPartitionBoundary IS NULL) + BEGIN + SET @precedingPartitionBoundary = CONVERT (DATETIME2 (7), N'1970-01-01T00:00:00.0000000'); + END + DECLARE @endDateTimeToFilter AS DATETIME2 (7) = DATEADD(HOUR, 1, SYSUTCDATETIME()); + WITH PartitionBoundaries + AS (SELECT CAST (prv.value AS DATETIME2 (7)) AS PartitionBoundary + FROM sys.partition_range_values AS prv WITH (NOLOCK) + INNER JOIN + sys.partition_functions AS pf WITH (NOLOCK) + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + AND SQL_VARIANT_PROPERTY(prv.Value, 'BaseType') = 'datetime2' + AND CAST (prv.value AS DATETIME2 (7)) BETWEEN @precedingPartitionBoundary AND @endDateTimeToFilter) + SELECT TOP (@pageSize) Id, + Timestamp, + ResourceId, + ResourceTypeId, + ResourceVersion, + ResourceChangeTypeId + FROM PartitionBoundaries AS p CROSS APPLY (SELECT TOP (@pageSize) Id, + Timestamp, + ResourceId, + ResourceTypeId, + ResourceVersion, + ResourceChangeTypeId + FROM dbo.ResourceChangeData WITH (TABLOCK, HOLDLOCK) + WHERE Id >= @startId + AND $PARTITION.PartitionFunction_ResourceChangeData_Timestamp (Timestamp) = $PARTITION.PartitionFunction_ResourceChangeData_Timestamp (p.PartitionBoundary) + ORDER BY Id ASC) AS rcd + ORDER BY rcd.Id ASC; +END + +GO +CREATE PROCEDURE dbo.GetActiveJobs +@QueueType TINYINT, @GroupId BIGINT=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetActiveJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL'), @st AS DATETIME = getUTCdate(), @JobIds AS BigintList, @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0, @Rows AS INT = 0; +BEGIN TRY + SET @PartitionId = @MaxPartitions * rand(); + WHILE @LookedAtPartitions < @MaxPartitions + BEGIN + IF @GroupId IS NULL + INSERT INTO @JobIds + SELECT JobId + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (0, 1); + ELSE + INSERT INTO @JobIds + SELECT JobId + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND GroupId = @GroupId + AND Status IN (0, 1); + SET @Rows += @@rowcount; + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions += 1; + END + IF @Rows > 0 + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetCommandsForRebuildIndexes +@RebuildClustered BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetCommandsForRebuildIndexes', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId RC=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100), @TblInt AS VARCHAR (100), @Ind AS VARCHAR (200), @IndId AS INT, @Supported AS BIT, @Txt AS VARCHAR (MAX), @Rows AS BIGINT, @Pages AS BIGINT, @ResourceTypeId AS SMALLINT, @IndexesCnt AS INT, @DataComp AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Commands TABLE ( + Tbl VARCHAR (100), + Ind VARCHAR (200), + Txt VARCHAR (MAX), + Pages BIGINT ); + DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY); + DECLARE @Indexes TABLE ( + Ind VARCHAR (200) PRIMARY KEY, + IndId INT ); + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + Supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SELECT TOP 1 @Tbl = name, + @Supported = Supported + FROM @Tables + ORDER BY name; + IF @Supported = 0 + BEGIN + INSERT INTO @Commands + SELECT @Tbl, + name, + 'ALTER INDEX ' + name + ' ON dbo.' + @Tbl + ' REBUILD' + CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = name) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END, + CONVERT (BIGINT, 9e18) + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (is_disabled = 1 + AND index_id > 1 + AND @RebuildClustered = 0 + OR index_id = 1 + AND @RebuildClustered = 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Commands', @Action = 'Insert', @Rows = @@rowcount, @Text = 'Not supported tables with disabled indexes'; + END + ELSE + BEGIN + DELETE @ResourceTypes; + INSERT INTO @ResourceTypes + SELECT CONVERT (SMALLINT, substring(name, charindex('_', name) + 1, 6)) AS ResourceTypeId + FROM sys.sysobjects + WHERE name LIKE @Tbl + '[_]%'; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@ResourceTypes', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @ResourceTypes + ORDER BY ResourceTypeId); + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + SET @Pages = (SELECT dpages + FROM sysindexes + WHERE id = object_id(@TblInt) + AND indid IN (0, 1)); + DELETE @Indexes; + INSERT INTO @Indexes + SELECT name, + index_id + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (index_id > 1 + AND @RebuildClustered = 0 + OR index_id = 1 + AND @RebuildClustered = 1); + SET @IndexesCnt = 0; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @Ind = Ind, + @IndId = IndId + FROM @Indexes + ORDER BY Ind; + IF @IndId = 1 + BEGIN + SET @Txt = 'ALTER INDEX ' + @Ind + ' ON dbo.' + @TblInt + ' REBUILD' + CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = @Ind) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END; + INSERT INTO @Commands + SELECT @TblInt, + @Ind, + @Txt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = @Txt; + END + ELSE + IF NOT EXISTS (SELECT * + FROM sys.indexes + WHERE object_id = object_id(@TblInt) + AND name = @Ind) + BEGIN + EXECUTE dbo.GetIndexCommands @Tbl = @Tbl, @Ind = @Ind, @AddPartClause = 0, @IncludeClustered = 0, @Txt = @Txt OUTPUT; + SET @Txt = replace(@Txt, '[' + @Tbl + ']', @TblInt); + IF @Txt IS NOT NULL + BEGIN + SET @IndexesCnt = @IndexesCnt + 1; + INSERT INTO @Commands + SELECT @TblInt, + @Ind, + @Txt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = @Txt; + END + END + DELETE @Indexes + WHERE Ind = @Ind; + END + IF @IndexesCnt > 1 + BEGIN + INSERT INTO @Commands + SELECT @TblInt, + 'UPDATE STAT', + 'UPDATE STATISTICS dbo.' + @TblInt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = 'Add stats update'; + END + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + END + DELETE @Tables + WHERE name = @Tbl; + END + SELECT Tbl, + Ind, + Txt + FROM @Commands + ORDER BY Pages DESC, Tbl, CASE WHEN Txt LIKE 'UPDATE STAT%' THEN 0 ELSE 1 END; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Commands', @Action = 'Select', @Rows = @@rowcount; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetIndexCommands +@Tbl VARCHAR (100), @Ind VARCHAR (200), @AddPartClause BIT, @IncludeClustered BIT, @Txt VARCHAR (MAX)=NULL OUTPUT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetIndexCommands', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL') + ' Ind=' + isnull(@Ind, 'NULL'), @st AS DATETIME = getUTCdate(); +DECLARE @Indexes TABLE ( + Ind VARCHAR (200) PRIMARY KEY, + Txt VARCHAR (MAX)); +BEGIN TRY + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT Ind, + CASE WHEN is_primary_key = 1 THEN 'ALTER TABLE dbo.[' + Tbl + '] ADD PRIMARY KEY ' + CASE WHEN type = 1 THEN ' CLUSTERED' ELSE '' END ELSE 'CREATE' + CASE WHEN is_unique = 1 THEN ' UNIQUE' ELSE '' END + CASE WHEN type = 1 THEN ' CLUSTERED' ELSE '' END + ' INDEX ' + Ind + ' ON dbo.[' + Tbl + ']' END + ' (' + KeyCols + ')' + IncClause + CASE WHEN filter_def IS NOT NULL THEN ' WHERE ' + filter_def ELSE '' END + CASE WHEN data_comp IS NOT NULL THEN ' WITH (DATA_COMPRESSION = ' + data_comp + ')' ELSE '' END + CASE WHEN @AddPartClause = 1 THEN PartClause ELSE '' END + FROM (SELECT O.Name AS Tbl, + I.Name AS Ind, + isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions AS P + WHERE P.object_id = I.object_id + AND I.index_id = P.index_id), (SELECT NULLIF (PropertyValue, 'NONE') + FROM dbo.IndexProperties + WHERE TableName = O.Name + AND IndexName = I.Name + AND PropertyName = 'DATA_COMPRESSION')) AS data_comp, + replace(replace(replace(replace(I.filter_definition, '[', ''), ']', ''), '(', ''), ')', '') AS filter_def, + I.is_unique, + I.is_primary_key, + I.type, + KeyCols, + CASE WHEN IncCols IS NOT NULL THEN ' INCLUDE (' + IncCols + ')' ELSE '' END AS IncClause, + CASE WHEN EXISTS (SELECT * + FROM sys.partition_schemes AS S + WHERE S.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') THEN ' ON PartitionScheme_ResourceTypeId (ResourceTypeId)' ELSE '' END AS PartClause + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id CROSS APPLY (SELECT string_agg(CASE WHEN IC.key_ordinal > 0 + AND IC.is_included_column = 0 THEN C.name END, ',') WITHIN GROUP (ORDER BY key_ordinal) AS KeyCols, + string_agg(CASE WHEN IC.is_included_column = 1 THEN C.name END, ',') WITHIN GROUP (ORDER BY key_ordinal) AS IncCols + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = IC.object_id + AND C.column_id = IC.column_id + WHERE IC.object_id = I.object_id + AND IC.index_id = I.index_id + GROUP BY IC.object_id, IC.index_id) AS IC + WHERE O.name = @Tbl + AND (@Ind IS NULL + OR I.name = @Ind) + AND (@IncludeClustered = 1 + OR index_id > 1)) AS A; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + IF @Ind IS NULL + SELECT Ind, + Txt + FROM @Indexes; + ELSE + SET @Txt = (SELECT Txt + FROM @Indexes); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = @Txt; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetJobs +@QueueType TINYINT, @JobId BIGINT=NULL, @JobIds BigintList READONLY, @GroupId BIGINT=NULL, @ReturnDefinition BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL'), @st AS DATETIME = getUTCdate(), @PartitionId AS TINYINT = @JobId % 16; +BEGIN TRY + IF @JobId IS NULL + AND @GroupId IS NULL + AND NOT EXISTS (SELECT * + FROM @JobIds) + RAISERROR ('@JobId = NULL and @GroupId = NULL and @JobIds is empty', 18, 127); + IF @JobId IS NOT NULL + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = isnull(@JobId, -1) + AND Status <> 5; + ELSE + IF @GroupId IS NOT NULL + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_GroupId)) + WHERE QueueType = @QueueType + AND GroupId = isnull(@GroupId, -1) + AND Status <> 5; + ELSE + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND JobId IN (SELECT Id + FROM @JobIds) + AND PartitionId = JobId % 16 + AND Status <> 5; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetPartitionedTables +@IncludeNotDisabled BIT=1, @IncludeNotSupported BIT=1 +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetPartitionedTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId D=' + isnull(CONVERT (VARCHAR, @IncludeNotDisabled), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @IncludeNotSupported), 'NULL'), @st AS DATETIME = getUTCdate(); +DECLARE @NotSupportedTables TABLE ( + id INT PRIMARY KEY); +BEGIN TRY + INSERT INTO @NotSupportedTables + SELECT DISTINCT O.object_id + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') + AND (NOT EXISTS (SELECT * + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = IC.object_id + AND C.column_id = IC.column_id + WHERE IC.object_id = I.object_id + AND IC.index_id = I.index_id + AND IC.key_ordinal > 0 + AND IC.is_included_column = 0 + AND C.name = 'ResourceTypeId') + OR EXISTS (SELECT * + FROM sys.indexes AS NSI + WHERE NSI.object_id = O.object_id + AND NOT EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = NSI.data_space_id + AND name = 'PartitionScheme_ResourceTypeId'))); + SELECT CONVERT (VARCHAR (100), O.name), + CONVERT (BIT, CASE WHEN EXISTS (SELECT * + FROM @NotSupportedTables AS NSI + WHERE NSI.id = O.object_id) THEN 0 ELSE 1 END) + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND I.index_id IN (0, 1) + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') + AND EXISTS (SELECT * + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = I.object_id + AND C.column_id = IC.column_id + AND IC.is_included_column = 0 + AND C.name = 'ResourceTypeId') + AND (@IncludeNotSupported = 1 + OR NOT EXISTS (SELECT * + FROM @NotSupportedTables AS NSI + WHERE NSI.id = O.object_id)) + AND (@IncludeNotDisabled = 1 + OR EXISTS (SELECT * + FROM sys.indexes AS D + WHERE D.object_id = O.object_id + AND D.is_disabled = 1)) + ORDER BY 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetReindexJobById +@id VARCHAR (64) +AS +SET NOCOUNT ON; +SELECT RawJobRecord, + JobVersion +FROM dbo.ReindexJob +WHERE Id = @id; + +GO +CREATE PROCEDURE dbo.GetResources +@ResourceKeys dbo.ResourceKeyList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResources', @InputRows AS INT, @DummyTop AS BIGINT = 9223372036854775807, @NotNullVersionExists AS BIT, @NullVersionExists AS BIT, @MinRT AS SMALLINT, @MaxRT AS SMALLINT; +SELECT @MinRT = min(ResourceTypeId), + @MaxRT = max(ResourceTypeId), + @InputRows = count(*), + @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), + @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) +FROM @ResourceKeys; +DECLARE @Mode AS VARCHAR (100) = 'RT=[' + CONVERT (VARCHAR, @MinRT) + ',' + CONVERT (VARCHAR, @MaxRT) + '] Cnt=' + CONVERT (VARCHAR, @InputRows) + ' NNVE=' + CONVERT (VARCHAR, @NotNullVersionExists) + ' NVE=' + CONVERT (VARCHAR, @NullVersionExists); +BEGIN TRY + IF @NotNullVersionExists = 1 + IF @NullVersionExists = 0 + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys) AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys + WHERE Version IS NOT NULL) AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys + WHERE Version IS NULL) AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0) AS A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys) AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourcesByTransactionId +@TransactionId BIGINT, @IncludeHistory BIT=0, @ReturnResourceKeysOnly BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId) + ' H=' + CONVERT (VARCHAR, @IncludeHistory), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807, @TypeId AS SMALLINT; +BEGIN TRY + DECLARE @Types TABLE ( + TypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + DECLARE @Keys TABLE ( + TypeId SMALLINT, + SurrogateId BIGINT PRIMARY KEY (TypeId, SurrogateId)); + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @TypeId = (SELECT TOP 1 TypeId + FROM @Types + ORDER BY TypeId); + INSERT INTO @Keys + SELECT @TypeId, + ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @TypeId + AND TransactionId = @TransactionId; + DELETE @Types + WHERE TypeId = @TypeId; + END + IF @ReturnResourceKeysOnly = 0 + SELECT ResourceTypeId, + ResourceId, + ResourceSurrogateId, + Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + RequestMethod + FROM (SELECT TOP (@DummyTop) * + FROM @Keys) AS A + INNER JOIN + dbo.Resource AS B + ON ResourceTypeId = TypeId + AND ResourceSurrogateId = SurrogateId + WHERE IsHistory = 0 + OR @IncludeHistory = 1 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT ResourceTypeId, + ResourceId, + ResourceSurrogateId, + Version, + IsDeleted + FROM (SELECT TOP (@DummyTop) * + FROM @Keys) AS A + INNER JOIN + dbo.Resource AS B + ON ResourceTypeId = TypeId + AND ResourceSurrogateId = SurrogateId + WHERE IsHistory = 0 + OR @IncludeHistory = 1 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange +@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @GlobalEndId BIGINT=NULL, @IncludeHistory BIT=0, @IncludeDeleted BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetResourcesByTypeAndSurrogateIdRange', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' GE=' + isnull(CONVERT (VARCHAR, @GlobalEndId), 'NULL') + ' HI=' + isnull(CONVERT (VARCHAR, @IncludeHistory), 'NULL') + ' DE' + isnull(CONVERT (VARCHAR, @IncludeDeleted), 'NULL'), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807; +BEGIN TRY + DECLARE @ResourceIds TABLE ( + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY); + DECLARE @SurrogateIds TABLE ( + MaxSurrogateId BIGINT PRIMARY KEY); + IF @GlobalEndId IS NOT NULL + AND @IncludeHistory = 0 + BEGIN + INSERT INTO @ResourceIds + SELECT DISTINCT ResourceId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + IF @@rowcount > 0 + INSERT INTO @SurrogateIds + SELECT ResourceSurrogateId + FROM (SELECT ResourceId, + ResourceSurrogateId, + row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) AS RowId + FROM dbo.Resource WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId + FROM @ResourceIds) + AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId) AS A + WHERE RowId = 1 + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + END + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND (IsHistory = 0 + OR @IncludeHistory = 1) + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource + FROM @SurrogateIds + INNER JOIN + dbo.Resource + ON ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceSearchParamStats +@Table VARCHAR (100)=NULL, @ResourceTypeId SMALLINT=NULL, @SearchParamId SMALLINT=NULL +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'T=' + isnull(@Table, 'NULL') + ' RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' SP=' + isnull(CONVERT (VARCHAR, @SearchParamId), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + SELECT T.name AS TableName, + S.name AS StatsName, + db_name() AS DatabaseName + FROM sys.stats AS S + INNER JOIN + sys.tables AS T + ON T.object_id = S.object_id + WHERE T.name LIKE '%SearchParam' + AND T.name <> 'SearchParam' + AND S.name LIKE 'ST[_]%' + AND (T.name LIKE @Table + OR @Table IS NULL) + AND (S.name LIKE '%ResourceTypeId[_]' + CONVERT (VARCHAR, @ResourceTypeId) + '[_]%' + OR @ResourceTypeId IS NULL) + AND (S.name LIKE '%SearchParamId[_]' + CONVERT (VARCHAR, @SearchParamId) + OR @SearchParamId IS NULL); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Rows = @@rowcount, @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceSurrogateIdRanges +@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @RangeSize INT, @NumberOfRanges INT=100, @Up BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetResourceSurrogateIdRanges', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' R=' + isnull(CONVERT (VARCHAR, @RangeSize), 'NULL') + ' UP=' + isnull(CONVERT (VARCHAR, @Up), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + IF @Up = 1 + SELECT RangeId, + min(ResourceSurrogateId), + max(ResourceSurrogateId), + count(*) + FROM (SELECT isnull(CONVERT (INT, (row_number() OVER (ORDER BY ResourceSurrogateId) - 1) / @RangeSize), 0) AS RangeId, + ResourceSurrogateId + FROM (SELECT TOP (@RangeSize * @NumberOfRanges) ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId >= @StartId + AND ResourceSurrogateId <= @EndId + ORDER BY ResourceSurrogateId) AS A) AS A + GROUP BY RangeId + OPTION (MAXDOP 1); + ELSE + SELECT RangeId, + min(ResourceSurrogateId), + max(ResourceSurrogateId), + count(*) + FROM (SELECT isnull(CONVERT (INT, (row_number() OVER (ORDER BY ResourceSurrogateId) - 1) / @RangeSize), 0) AS RangeId, + ResourceSurrogateId + FROM (SELECT TOP (@RangeSize * @NumberOfRanges) ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId >= @StartId + AND ResourceSurrogateId <= @EndId + ORDER BY ResourceSurrogateId DESC) AS A) AS A + GROUP BY RangeId + OPTION (MAXDOP 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceVersions +@ResourceDateKeys dbo.ResourceDateKeyList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResourceVersions', @Mode AS VARCHAR (100) = 'Rows=' + CONVERT (VARCHAR, (SELECT count(*) + FROM @ResourceDateKeys)), @DummyTop AS BIGINT = 9223372036854775807; +BEGIN TRY + SELECT A.ResourceTypeId, + A.ResourceId, + A.ResourceSurrogateId, + CASE WHEN D.Version IS NOT NULL THEN 0 WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex ELSE isnull(M.Version, 0) - ResourceIndex END AS Version, + isnull(D.Version, 0) AS MatchedVersion, + D.RawResource AS MatchedRawResource + FROM (SELECT TOP (@DummyTop) *, + CONVERT (INT, row_number() OVER (PARTITION BY ResourceTypeId, ResourceId ORDER BY ResourceSurrogateId DESC)) AS ResourceIndex + FROM @ResourceDateKeys) AS A OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version > 0 + AND B.ResourceSurrogateId < A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId DESC) AS L OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version > 0 + AND B.ResourceSurrogateId > A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId) AS U OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version < 0 + ORDER BY B.Version) AS M OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) AS D + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetSearchParamStatuses +AS +SET NOCOUNT ON; +SELECT SearchParamId, + Uri, + Status, + LastUpdated, + IsPartiallySupported +FROM dbo.SearchParam; + +GO +CREATE PROCEDURE dbo.GetTransactions +@StartNotInclusiveTranId BIGINT, @EndInclusiveTranId BIGINT, @EndDate DATETIME=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'ST=' + CONVERT (VARCHAR, @StartNotInclusiveTranId) + ' ET=' + CONVERT (VARCHAR, @EndInclusiveTranId) + ' ED=' + isnull(CONVERT (VARCHAR, @EndDate, 121), 'NULL'), @st AS DATETIME = getUTCdate(); +IF @EndDate IS NULL + SET @EndDate = getUTCdate(); +SELECT SurrogateIdRangeFirstValue, + VisibleDate, + InvisibleHistoryRemovedDate +FROM dbo.Transactions +WHERE SurrogateIdRangeFirstValue > @StartNotInclusiveTranId + AND SurrogateIdRangeFirstValue <= @EndInclusiveTranId + AND EndDate <= @EndDate +ORDER BY SurrogateIdRangeFirstValue; +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; + +GO +CREATE PROCEDURE dbo.GetUsedResourceTypes +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetUsedResourceTypes', @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(); +BEGIN TRY + SELECT ResourceTypeId, + Name + FROM dbo.ResourceType AS A + WHERE EXISTS (SELECT * + FROM dbo.Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.HardDeleteResource +@ResourceTypeId SMALLINT, @ResourceId VARCHAR (64), @KeepCurrentVersion BIT, @IsResourceChangeCaptureEnabled BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'RT=' + CONVERT (VARCHAR, @ResourceTypeId) + ' R=' + @ResourceId + ' V=' + CONVERT (VARCHAR, @KeepCurrentVersion) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled), @st AS DATETIME = getUTCdate(), @TransactionId AS BIGINT; +BEGIN TRY + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUTPUT; + IF @KeepCurrentVersion = 0 + BEGIN TRANSACTION; + DECLARE @SurrogateIds TABLE ( + ResourceSurrogateId BIGINT NOT NULL); + IF @IsResourceChangeCaptureEnabled = 1 + AND NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'InvisibleHistory.IsEnabled' + AND Number = 0) + UPDATE dbo.Resource + SET IsDeleted = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1) + AND RawResource <> 0xF; + ELSE + DELETE dbo.Resource + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1) + AND RawResource <> 0xF; + IF @KeepCurrentVersion = 0 + BEGIN + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ResourceWriteClaim AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ReferenceSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenText AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.StringSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.UriSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.NumberSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.QuantitySearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.DateTimeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ReferenceTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenDateTimeCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenQuantityCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenStringCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenNumberNumberCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + END + IF @@trancount > 0 + COMMIT TRANSACTION; + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.InitializeIndexProperties +AS +SET NOCOUNT ON; +INSERT INTO dbo.IndexProperties (TableName, IndexName, PropertyName, PropertyValue) +SELECT Tbl, + Ind, + 'DATA_COMPRESSION', + isnull(data_comp, 'NONE') +FROM (SELECT O.Name AS Tbl, + I.Name AS Ind, + (SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions AS P + WHERE P.object_id = I.object_id + AND I.index_id = P.index_id) AS data_comp + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId')) AS A +WHERE NOT EXISTS (SELECT * + FROM dbo.IndexProperties + WHERE TableName = Tbl + AND IndexName = Ind); + +GO +CREATE PROCEDURE dbo.LogEvent +@Process VARCHAR (100), @Status VARCHAR (10), @Mode VARCHAR (200)=NULL, @Action VARCHAR (20)=NULL, @Target VARCHAR (100)=NULL, @Rows BIGINT=NULL, @Start DATETIME=NULL, @Text NVARCHAR (3500)=NULL, @EventId BIGINT=NULL OUTPUT, @Retry INT=NULL +AS +SET NOCOUNT ON; +DECLARE @ErrorNumber AS INT = error_number(), @ErrorMessage AS VARCHAR (1000) = '', @TranCount AS INT = @@trancount, @DoWork AS BIT = 0, @NumberAdded AS BIT; +IF @ErrorNumber IS NOT NULL + OR @Status IN ('Warn', 'Error') + SET @DoWork = 1; +IF @DoWork = 0 + SET @DoWork = CASE WHEN EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = isnull(@Process, '') + AND Char = 'LogEvent') THEN 1 ELSE 0 END; +IF @DoWork = 0 + RETURN; +IF @ErrorNumber IS NOT NULL + SET @ErrorMessage = CASE WHEN @Retry IS NOT NULL THEN 'Retry ' + CONVERT (VARCHAR, @Retry) + ', ' ELSE '' END + 'Error ' + CONVERT (VARCHAR, error_number()) + ': ' + CONVERT (VARCHAR (1000), error_message()) + ', Level ' + CONVERT (VARCHAR, error_severity()) + ', State ' + CONVERT (VARCHAR, error_state()) + CASE WHEN error_procedure() IS NOT NULL THEN ', Procedure ' + error_procedure() ELSE '' END + ', Line ' + CONVERT (VARCHAR, error_line()); +IF @TranCount > 0 + AND @ErrorNumber IS NOT NULL + ROLLBACK; +IF databasepropertyex(db_name(), 'UpdateAbility') = 'READ_WRITE' + BEGIN + INSERT INTO dbo.EventLog (Process, Status, Mode, Action, Target, Rows, Milliseconds, EventDate, EventText, SPID, HostName) + SELECT @Process, + @Status, + @Mode, + @Action, + @Target, + @Rows, + datediff(millisecond, @Start, getUTCdate()), + getUTCdate() AS EventDate, + CASE WHEN @ErrorNumber IS NULL THEN @Text ELSE @ErrorMessage + CASE WHEN isnull(@Text, '') <> '' THEN '. ' + @Text ELSE '' END END AS Text, + @@SPID, + host_name() AS HostName; + SET @EventId = scope_identity(); + END +IF @TranCount > 0 + AND @ErrorNumber IS NOT NULL + BEGIN TRANSACTION; + +GO +CREATE PROCEDURE dbo.LogSchemaMigrationProgress +@message VARCHAR (MAX) +AS +INSERT INTO dbo.SchemaMigrationProgress (Message) +VALUES (@message); + +GO +CREATE PROCEDURE dbo.MergeResources +@AffectedRows INT=0 OUTPUT, @RaiseExceptionOnConflict BIT=1, @IsResourceChangeCaptureEnabled BIT=0, @TransactionId BIGINT=NULL, @SingleTransaction BIT=1, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParms dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0; +DECLARE @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) + FROM @Resources), 'Input=Empty'); +SET @Mode += ' E=' + CONVERT (VARCHAR, @RaiseExceptionOnConflict) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled) + ' IT=' + CONVERT (VARCHAR, @InitialTranCount) + ' T=' + isnull(CONVERT (VARCHAR, @TransactionId), 'NULL'); +SET @AffectedRows = 0; +BEGIN TRY + DECLARE @Existing AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)); + DECLARE @ResourceInfos AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL, + Version INT NOT NULL, + KeepHistory BIT NOT NULL, + PreviousVersion INT NULL, + PreviousSurrogateId BIGINT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)); + DECLARE @PreviousSurrogateIds AS TABLE ( + TypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL PRIMARY KEY (TypeId, SurrogateId), + KeepHistory BIT ); + IF @SingleTransaction = 0 + AND isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'MergeResources.NoTransaction.IsEnabled'), 0) = 0 + SET @SingleTransaction = 1; + SET @Mode += ' ST=' + CONVERT (VARCHAR, @SingleTransaction); + IF @InitialTranCount = 0 + BEGIN + IF EXISTS (SELECT * + FROM @Resources AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId) + BEGIN + BEGIN TRANSACTION; + INSERT INTO @Existing (ResourceTypeId, SurrogateId) + SELECT B.ResourceTypeId, + B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * + FROM @Resources) AS A + INNER JOIN + dbo.Resource AS B WITH (ROWLOCK, HOLDLOCK) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0 + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + IF @@rowcount = (SELECT count(*) + FROM @Resources) + SET @IsRetry = 1; + IF @IsRetry = 0 + COMMIT TRANSACTION; + END + END + SET @Mode += ' R=' + CONVERT (VARCHAR, @IsRetry); + IF @SingleTransaction = 1 + AND @@trancount = 0 + BEGIN TRANSACTION; + IF @IsRetry = 0 + BEGIN + INSERT INTO @ResourceInfos (ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId) + SELECT A.ResourceTypeId, + A.ResourceSurrogateId, + A.Version, + A.KeepHistory, + B.Version, + B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * + FROM @Resources + WHERE HasVersionToCompare = 1) AS A + LEFT OUTER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.IsHistory = 0 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + IF @RaiseExceptionOnConflict = 1 + AND EXISTS (SELECT * + FROM @ResourceInfos + WHERE PreviousVersion IS NOT NULL + AND Version <= PreviousVersion) + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + INSERT INTO @PreviousSurrogateIds + SELECT ResourceTypeId, + PreviousSurrogateId, + KeepHistory + FROM @ResourceInfos + WHERE PreviousSurrogateId IS NOT NULL; + IF @@rowcount > 0 + BEGIN + UPDATE dbo.Resource + SET IsHistory = 1 + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 1); + SET @AffectedRows += @@rowcount; + IF @IsResourceChangeCaptureEnabled = 1 + AND NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'InvisibleHistory.IsEnabled' + AND Number = 0) + UPDATE dbo.Resource + SET IsHistory = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 0); + ELSE + DELETE dbo.Resource + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 0); + SET @AffectedRows += @@rowcount; + DELETE dbo.ResourceWriteClaim + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.ReferenceSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenText + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.StringSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.UriSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.NumberSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.QuantitySearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.DateTimeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.ReferenceTokenCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenTokenCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenDateTimeCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenQuantityCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenStringCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenNumberNumberCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + END + INSERT INTO dbo.Resource (ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId) + SELECT ResourceTypeId, + ResourceId, + Version, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + @TransactionId + FROM @Resources; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM @ResourceWriteClaims; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceId, + ReferenceResourceVersion + FROM @ReferenceSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM @TokenSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM @TokenTexts; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM @StringSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM @UriSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM @NumberSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM @QuantitySearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM @DateTimeSearchParms; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM @TokenTokenCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM @TokenQuantityCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM @TokenStringCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM @TokenNumberNumberCompositeSearchParams; + SET @AffectedRows += @@rowcount; + END + ELSE + BEGIN + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceWriteClaims) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.ResourceWriteClaim AS C + WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceId, + ReferenceResourceVersion + FROM (SELECT TOP (@DummyTop) * + FROM @ReferenceSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.ReferenceSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM (SELECT TOP (@DummyTop) * + FROM @TokenSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM (SELECT TOP (@DummyTop) * + FROM @TokenTexts) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM (SELECT TOP (@DummyTop) * + FROM @StringSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenText AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM (SELECT TOP (@DummyTop) * + FROM @UriSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.UriSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM (SELECT TOP (@DummyTop) * + FROM @NumberSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.NumberSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM (SELECT TOP (@DummyTop) * + FROM @QuantitySearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.QuantitySearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM (SELECT TOP (@DummyTop) * + FROM @DateTimeSearchParms) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @ReferenceTokenCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.DateTimeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenTokenCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenTokenCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenDateTimeCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenDateTimeCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenQuantityCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenQuantityCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenStringCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenStringCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM (SELECT TOP (@DummyTop) * + FROM @TokenNumberNumberCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenNumberNumberCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + END + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.CaptureResourceIdsForChanges @Resources; + IF @TransactionId IS NOT NULL + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + IF @InitialTranCount = 0 + AND @@trancount > 0 + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 + AND @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + IF @RaiseExceptionOnConflict = 1 + AND error_number() IN (2601, 2627) + AND (error_message() LIKE '%''dbo.Resource%' + OR error_message() LIKE '%''dbo.RawResources''%') + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesAdvanceTransactionVisibility +@AffectedRows INT=0 OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(), @msg AS VARCHAR (1000), @MaxTransactionId AS BIGINT, @MinTransactionId AS BIGINT, @MinNotCompletedTransactionId AS BIGINT, @CurrentTransactionId AS BIGINT; +SET @AffectedRows = 0; +BEGIN TRY + EXECUTE dbo.MergeResourcesGetTransactionVisibility @MinTransactionId OUTPUT; + SET @MinTransactionId += 1; + SET @CurrentTransactionId = (SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + ORDER BY SurrogateIdRangeFirstValue DESC); + SET @MinNotCompletedTransactionId = isnull((SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsCompleted = 0 + AND SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + ORDER BY SurrogateIdRangeFirstValue), @CurrentTransactionId + 1); + SET @MaxTransactionId = (SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsCompleted = 1 + AND SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + AND SurrogateIdRangeFirstValue < @MinNotCompletedTransactionId + ORDER BY SurrogateIdRangeFirstValue DESC); + IF @MaxTransactionId >= @MinTransactionId + BEGIN + UPDATE A + SET IsVisible = 1, + VisibleDate = getUTCdate() + FROM dbo.Transactions AS A WITH (INDEX (1)) + WHERE SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + AND SurrogateIdRangeFirstValue <= @MaxTransactionId; + SET @AffectedRows += @@rowcount; + END + SET @msg = 'Min=' + CONVERT (VARCHAR, @MinTransactionId) + ' C=' + CONVERT (VARCHAR, @CurrentTransactionId) + ' MinNC=' + CONVERT (VARCHAR, @MinNotCompletedTransactionId) + ' Max=' + CONVERT (VARCHAR, @MaxTransactionId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows, @Text = @msg; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesBeginTransaction +@Count INT, @TransactionId BIGINT OUTPUT, @SequenceRangeFirstValue INT=NULL OUTPUT, @HeartbeatDate DATETIME=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesBeginTransaction', @Mode AS VARCHAR (200) = 'Cnt=' + CONVERT (VARCHAR, @Count), @st AS DATETIME = getUTCdate(), @FirstValueVar AS SQL_VARIANT, @LastValueVar AS SQL_VARIANT; +BEGIN TRY + SET @TransactionId = NULL; + IF @@trancount > 0 + RAISERROR ('MergeResourcesBeginTransaction cannot be called inside outer transaction.', 18, 127); + SET @FirstValueVar = NULL; + WHILE @FirstValueVar IS NULL + BEGIN + EXECUTE sys.sp_sequence_get_range @sequence_name = 'dbo.ResourceSurrogateIdUniquifierSequence', @range_size = @Count, @range_first_value = @FirstValueVar OUTPUT, @range_last_value = @LastValueVar OUTPUT; + SET @SequenceRangeFirstValue = CONVERT (INT, @FirstValueVar); + IF @SequenceRangeFirstValue > CONVERT (INT, @LastValueVar) + SET @FirstValueVar = NULL; + END + SET @TransactionId = datediff_big(millisecond, '0001-01-01', sysUTCdatetime()) * 80000 + @SequenceRangeFirstValue; + INSERT INTO dbo.Transactions (SurrogateIdRangeFirstValue, SurrogateIdRangeLastValue, HeartbeatDate) + SELECT @TransactionId, + @TransactionId + @Count - 1, + isnull(@HeartbeatDate, getUTCdate()); +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesCommitTransaction +@TransactionId BIGINT, @FailureReason VARCHAR (MAX)=NULL, @OverrideIsControlledByClientCheck BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesCommitTransaction', @st AS DATETIME = getUTCdate(), @InitialTranCount AS INT = @@trancount, @IsCompletedBefore AS BIT, @Rows AS INT, @msg AS VARCHAR (1000); +DECLARE @Mode AS VARCHAR (200) = 'TR=' + CONVERT (VARCHAR, @TransactionId) + ' OC=' + isnull(CONVERT (VARCHAR, @OverrideIsControlledByClientCheck), 'NULL'); +BEGIN TRY + IF @InitialTranCount = 0 + BEGIN TRANSACTION; + UPDATE dbo.Transactions + SET IsCompleted = 1, + @IsCompletedBefore = IsCompleted, + EndDate = getUTCdate(), + IsSuccess = CASE WHEN @FailureReason IS NULL THEN 1 ELSE 0 END, + FailureReason = @FailureReason + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND (IsControlledByClient = 1 + OR @OverrideIsControlledByClientCheck = 1); + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + SET @msg = 'Transaction [' + CONVERT (VARCHAR (20), @TransactionId) + '] is not controlled by client or does not exist.'; + RAISERROR (@msg, 18, 127); + END + IF @IsCompletedBefore = 1 + BEGIN + IF @InitialTranCount = 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Target = '@IsCompletedBefore', @Text = '=1'; + RETURN; + END + IF @InitialTranCount = 0 + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 + AND @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory +@TransactionId BIGINT, @AffectedRows INT=NULL OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(), @TypeId AS SMALLINT; +SET @AffectedRows = 0; +BEGIN TRY + DECLARE @Types TABLE ( + TypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @TypeId = (SELECT TOP 1 TypeId + FROM @Types + ORDER BY TypeId); + DELETE dbo.Resource + WHERE ResourceTypeId = @TypeId + AND HistoryTransactionId = @TransactionId + AND RawResource = 0xF; + SET @AffectedRows += @@rowcount; + DELETE @Types + WHERE TypeId = @TypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesGetTimeoutTransactions +@TimeoutSec INT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TimeoutSec), @st AS DATETIME = getUTCdate(), @MinTransactionId AS BIGINT; +BEGIN TRY + EXECUTE dbo.MergeResourcesGetTransactionVisibility @MinTransactionId OUTPUT; + SELECT SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE SurrogateIdRangeFirstValue > @MinTransactionId + AND IsCompleted = 0 + AND datediff(second, HeartbeatDate, getUTCdate()) > @TimeoutSec + ORDER BY SurrogateIdRangeFirstValue; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesGetTransactionVisibility +@TransactionId BIGINT OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(); +SET @TransactionId = isnull((SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsVisible = 1 + ORDER BY SurrogateIdRangeFirstValue DESC), -1); +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount, @Text = @TransactionId; + +GO +CREATE PROCEDURE dbo.MergeResourcesPutTransactionHeartbeat +@TransactionId BIGINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesPutTransactionHeartbeat', @Mode AS VARCHAR (100) = 'TR=' + CONVERT (VARCHAR, @TransactionId); +BEGIN TRY + UPDATE dbo.Transactions + SET HeartbeatDate = getUTCdate() + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND IsControlledByClient = 1; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesPutTransactionInvisibleHistory +@TransactionId BIGINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'TR=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(); +BEGIN TRY + UPDATE dbo.Transactions + SET InvisibleHistoryRemovedDate = getUTCdate() + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND InvisibleHistoryRemovedDate IS NULL; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobCancelation +@QueueType TINYINT, @GroupId BIGINT=NULL, @JobId BIGINT=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobCancelation', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL') + ' J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL'), @st AS DATETIME = getUTCdate(), @Rows AS INT, @PartitionId AS TINYINT = @JobId % 16; +BEGIN TRY + IF @JobId IS NULL + AND @GroupId IS NULL + RAISERROR ('@JobId = NULL and @GroupId = NULL', 18, 127); + IF @JobId IS NOT NULL + BEGIN + UPDATE dbo.JobQueue + SET Status = 4, + EndDate = getUTCdate(), + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 0; + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + UPDATE dbo.JobQueue + SET CancelRequested = 1 + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1; + SET @Rows = @@rowcount; + END + END + ELSE + BEGIN + UPDATE dbo.JobQueue + SET Status = 4, + EndDate = getUTCdate(), + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()) + WHERE QueueType = @QueueType + AND GroupId = @GroupId + AND Status = 0; + SET @Rows = @@rowcount; + UPDATE dbo.JobQueue + SET CancelRequested = 1 + WHERE QueueType = @QueueType + AND GroupId = @GroupId + AND Status = 1; + SET @Rows += @@rowcount; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobHeartbeat +@QueueType TINYINT, @JobId BIGINT, @Version BIGINT, @Data BIGINT=NULL, @CancelRequested BIT=0 OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobHeartbeat', @Mode AS VARCHAR (100), @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT = @JobId % 16; +SET @Mode = 'Q=' + CONVERT (VARCHAR, @QueueType) + ' J=' + CONVERT (VARCHAR, @JobId) + ' P=' + CONVERT (VARCHAR, @PartitionId) + ' V=' + CONVERT (VARCHAR, @Version) + ' D=' + isnull(CONVERT (VARCHAR, @Data), 'NULL'); +BEGIN TRY + UPDATE dbo.JobQueue + SET @CancelRequested = CancelRequested, + HeartbeatDate = getUTCdate() + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1 + AND Version = @Version; + SET @Rows = @@rowcount; + IF @Rows = 0 + AND NOT EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Version = @Version + AND Status IN (2, 3, 4)) + BEGIN + IF EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId) + THROW 50412, 'Precondition failed', 1; + ELSE + THROW 50404, 'Job record not found', 1; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobStatus +@QueueType TINYINT, @JobId BIGINT, @Version BIGINT, @Failed BIT, @Data BIGINT, @FinalResult VARCHAR (MAX), @RequestCancellationOnFailure BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobStatus', @Mode AS VARCHAR (100), @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT = @JobId % 16, @GroupId AS BIGINT; +SET @Mode = 'Q=' + CONVERT (VARCHAR, @QueueType) + ' J=' + CONVERT (VARCHAR, @JobId) + ' P=' + CONVERT (VARCHAR, @PartitionId) + ' V=' + CONVERT (VARCHAR, @Version) + ' F=' + CONVERT (VARCHAR, @Failed) + ' R=' + isnull(@FinalResult, 'NULL'); +BEGIN TRY + UPDATE dbo.JobQueue + SET EndDate = getUTCdate(), + Status = CASE WHEN @Failed = 1 THEN 3 WHEN CancelRequested = 1 THEN 4 ELSE 2 END, + Data = @Data, + Result = @FinalResult, + @GroupId = GroupId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1 + AND Version = @Version; + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + SET @GroupId = (SELECT GroupId + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Version = @Version + AND Status IN (2, 3, 4)); + IF @GroupId IS NULL + IF EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId) + THROW 50412, 'Precondition failed', 1; + ELSE + THROW 50404, 'Job record not found', 1; + END + IF @Failed = 1 + AND @RequestCancellationOnFailure = 1 + EXECUTE dbo.PutJobCancelation @QueueType = @QueueType, @GroupId = @GroupId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.RemovePartitionFromResourceChanges_2 +@partitionNumberToSwitchOut INT, @partitionBoundaryToMerge DATETIME2 (7) +AS +BEGIN + TRUNCATE TABLE dbo.ResourceChangeDataStaging; + ALTER TABLE dbo.ResourceChangeData SWITCH PARTITION @partitionNumberToSwitchOut TO dbo.ResourceChangeDataStaging; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + MERGE RANGE (@partitionBoundaryToMerge); + TRUNCATE TABLE dbo.ResourceChangeDataStaging; +END + +GO +CREATE PROCEDURE dbo.SwitchPartitionsIn +@Tbl VARCHAR (100) +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsIn', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL'), @st AS DATETIME = getUTCdate(), @ResourceTypeId AS SMALLINT, @Rows AS BIGINT, @Txt AS VARCHAR (1000), @TblInt AS VARCHAR (100), @Ind AS VARCHAR (200), @IndId AS INT, @DataComp AS VARCHAR (100); +DECLARE @Indexes TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200)); +DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT index_id, + name + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND is_disabled = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @IndId = IndId, + @Ind = name + FROM @Indexes + ORDER BY IndId; + SET @DataComp = CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = @Ind) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END; + SET @Txt = 'IF EXISTS (SELECT * FROM sys.indexes WHERE object_id = object_id(''' + @Tbl + ''') AND name = ''' + @Ind + ''' AND is_disabled = 1) ALTER INDEX ' + @Ind + ' ON dbo.' + @Tbl + ' REBUILD' + @DataComp; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Ind, @Action = 'Rebuild', @Text = @Txt; + DELETE @Indexes + WHERE IndId = @IndId; + END + INSERT INTO @ResourceTypes + SELECT CONVERT (SMALLINT, substring(name, charindex('_', name) + 1, 6)) AS ResourceTypeId + FROM sys.objects AS O + WHERE name LIKE @Tbl + '[_]%' + AND EXISTS (SELECT * + FROM sysindexes + WHERE id = O.object_id + AND indid IN (0, 1) + AND rows > 0); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '#ResourceTypes', @Action = 'Select Into', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @ResourceTypes); + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt; + SET @Txt = 'ALTER TABLE dbo.' + @TblInt + ' SWITCH TO dbo.' + @Tbl + ' PARTITION $partition.PartitionFunction_ResourceTypeId(' + CONVERT (VARCHAR, @ResourceTypeId) + ')'; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch in start', @Text = @Txt; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch in', @Text = @Txt; + IF EXISTS (SELECT * + FROM sysindexes + WHERE id = object_id(@TblInt) + AND rows > 0) + BEGIN + SET @Txt = @TblInt + ' is not empty after switch'; + RAISERROR (@Txt, 18, 127); + END + EXECUTE ('DROP TABLE dbo.' + @TblInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Drop'; + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsInAllTables +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsInAllTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId', @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SET @Tbl = (SELECT TOP 1 name + FROM @Tables + ORDER BY name); + EXECUTE dbo.SwitchPartitionsIn @Tbl = @Tbl; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'SwitchPartitionsIn', @Action = 'Execute', @Text = @Tbl; + DELETE @Tables + WHERE name = @Tbl; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsOut +@Tbl VARCHAR (100), @RebuildClustered BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsOut', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL') + ' ND=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @ResourceTypeId AS SMALLINT, @Rows AS BIGINT, @Txt AS VARCHAR (MAX), @TblInt AS VARCHAR (100), @IndId AS INT, @Ind AS VARCHAR (200), @Name AS VARCHAR (100), @checkName AS VARCHAR (200), @definition AS VARCHAR (200); +DECLARE @Indexes TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200), + IsDisabled BIT ); +DECLARE @IndexesRT TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200), + IsDisabled BIT ); +DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY, + partition_number_roundtrip INT , + partition_number INT , + row_count BIGINT ); +DECLARE @Names TABLE ( + name VARCHAR (100) PRIMARY KEY); +DECLARE @CheckConstraints TABLE ( + CheckName VARCHAR (200), + CheckDefinition VARCHAR (200)); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + IF @RebuildClustered IS NULL + RAISERROR ('@RebuildClustered IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT index_id, + name, + is_disabled + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (is_disabled = 0 + OR @RebuildClustered = 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + INSERT INTO @ResourceTypes + SELECT partition_number - 1 AS ResourceTypeId, + $PARTITION.PartitionFunction_ResourceTypeId (partition_number - 1) AS partition_number_roundtrip, + partition_number, + row_count + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@Tbl) + AND index_id = 1 + AND row_count > 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@ResourceTypes', @Action = 'Insert', @Rows = @@rowcount, @Text = 'For partition switch'; + IF EXISTS (SELECT * + FROM @ResourceTypes + WHERE partition_number_roundtrip <> partition_number) + RAISERROR ('Partition sanity check failed', 18, 127); + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SELECT TOP 1 @ResourceTypeId = ResourceTypeId, + @Rows = row_count + FROM @ResourceTypes + ORDER BY ResourceTypeId; + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + SET @Txt = 'Starting @ResourceTypeId=' + CONVERT (VARCHAR, @ResourceTypeId) + ' row_count=' + CONVERT (VARCHAR, @Rows); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Text = @Txt; + IF NOT EXISTS (SELECT * + FROM sysindexes + WHERE id = object_id(@TblInt) + AND rows > 0) + BEGIN + IF object_id(@TblInt) IS NOT NULL + BEGIN + EXECUTE ('DROP TABLE dbo.' + @TblInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Drop'; + END + EXECUTE ('SELECT * INTO dbo.' + @TblInt + ' FROM dbo.' + @Tbl + ' WHERE 1 = 2'); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Select Into', @Rows = @@rowcount; + DELETE @CheckConstraints; + INSERT INTO @CheckConstraints + SELECT name, + definition + FROM sys.check_constraints + WHERE parent_object_id = object_id(@Tbl); + WHILE EXISTS (SELECT * + FROM @CheckConstraints) + BEGIN + SELECT TOP 1 @checkName = CheckName, + @definition = CheckDefinition + FROM @CheckConstraints; + SET @Txt = 'ALTER TABLE ' + @TblInt + ' ADD CHECK ' + @definition; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'ALTER', @Text = @Txt; + DELETE @CheckConstraints + WHERE CheckName = @checkName; + END + DELETE @Names; + INSERT INTO @Names + SELECT name + FROM sys.columns + WHERE object_id = object_id(@Tbl) + AND is_sparse = 1; + WHILE EXISTS (SELECT * + FROM @Names) + BEGIN + SET @Name = (SELECT TOP 1 name + FROM @Names + ORDER BY name); + SET @Txt = (SELECT 'ALTER TABLE dbo.' + @TblInt + ' ALTER COLUMN ' + @Name + ' ' + T.name + '(' + CONVERT (VARCHAR, C.precision) + ',' + CONVERT (VARCHAR, C.scale) + ') SPARSE NULL' + FROM sys.types AS T + INNER JOIN + sys.columns AS C + ON C.system_type_id = T.system_type_id + WHERE C.object_id = object_id(@Tbl) + AND C.name = @Name); + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'ALTER', @Text = @Txt; + DELETE @Names + WHERE name = @Name; + END + END + INSERT INTO @IndexesRT + SELECT * + FROM @Indexes + WHERE IsDisabled = 0; + WHILE EXISTS (SELECT * + FROM @IndexesRT) + BEGIN + SELECT TOP 1 @IndId = IndId, + @Ind = name + FROM @IndexesRT + ORDER BY IndId; + IF NOT EXISTS (SELECT * + FROM sys.indexes + WHERE object_id = object_id(@TblInt) + AND name = @Ind) + BEGIN + EXECUTE dbo.GetIndexCommands @Tbl = @Tbl, @Ind = @Ind, @AddPartClause = 0, @IncludeClustered = 1, @Txt = @Txt OUTPUT; + SET @Txt = replace(@Txt, '[' + @Tbl + ']', @TblInt); + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Create Index', @Text = @Txt; + END + DELETE @IndexesRT + WHERE IndId = @IndId; + END + SET @Txt = 'ALTER TABLE dbo.' + @TblInt + ' ADD CHECK (ResourceTypeId >= ' + CONVERT (VARCHAR, @ResourceTypeId) + ' AND ResourceTypeId < ' + CONVERT (VARCHAR, @ResourceTypeId) + ' + 1)'; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Add check', @Text = @Txt; + SET @Txt = 'ALTER TABLE dbo.' + @Tbl + ' SWITCH PARTITION $partition.PartitionFunction_ResourceTypeId(' + CONVERT (VARCHAR, @ResourceTypeId) + ') TO dbo.' + @TblInt; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch out start', @Text = @Txt; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch out end', @Text = @Txt; + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsOutAllTables +@RebuildClustered BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsOutAllTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId ND=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = @RebuildClustered, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SET @Tbl = (SELECT TOP 1 name + FROM @Tables + ORDER BY name); + EXECUTE dbo.SwitchPartitionsOut @Tbl = @Tbl, @RebuildClustered = @RebuildClustered; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'SwitchPartitionsOut', @Action = 'Execute', @Text = @Tbl; + DELETE @Tables + WHERE name = @Tbl; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +GO +CREATE OR ALTER PROCEDURE dbo.UpdateEventAgentCheckpoint +@CheckpointId VARCHAR (64), @LastProcessedDateTime DATETIMEOFFSET (7)=NULL, @LastProcessedIdentifier VARCHAR (64)=NULL +AS +BEGIN + IF EXISTS (SELECT * + FROM dbo.EventAgentCheckpoint + WHERE CheckpointId = @CheckpointId) + UPDATE dbo.EventAgentCheckpoint + SET CheckpointId = @CheckpointId, + LastProcessedDateTime = @LastProcessedDateTime, + LastProcessedIdentifier = @LastProcessedIdentifier, + UpdatedOn = sysutcdatetime() + WHERE CheckpointId = @CheckpointId; + ELSE + INSERT INTO dbo.EventAgentCheckpoint (CheckpointId, LastProcessedDateTime, LastProcessedIdentifier, UpdatedOn) + VALUES (@CheckpointId, @LastProcessedDateTime, @LastProcessedIdentifier, sysutcdatetime()); +END + +GO +CREATE PROCEDURE dbo.UpdateReindexJob +@id VARCHAR (64), @status VARCHAR (10), @rawJobRecord VARCHAR (MAX), @jobVersion BINARY (8) +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +BEGIN TRANSACTION; +DECLARE @currentJobVersion AS BINARY (8); +SELECT @currentJobVersion = JobVersion +FROM dbo.ReindexJob WITH (UPDLOCK, HOLDLOCK) +WHERE Id = @id; +IF (@currentJobVersion IS NULL) + BEGIN + THROW 50404, 'Reindex job record not found', 1; + END +IF (@jobVersion <> @currentJobVersion) + BEGIN + THROW 50412, 'Precondition failed', 1; + END +DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); +UPDATE dbo.ReindexJob +SET Status = @status, + HeartbeatDateTime = @heartbeatDateTime, + RawJobRecord = @rawJobRecord +WHERE Id = @id; +SELECT @@DBTS; +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.UpdateResourceSearchParams +@FailedResources INT=0 OUTPUT, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParams dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) + FROM @Resources), 'Input=Empty'), @Rows AS INT; +BEGIN TRY + DECLARE @Ids TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL); + BEGIN TRANSACTION; + UPDATE A + SET SearchParamHash = (SELECT SearchParamHash + FROM @Resources AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId) + FROM dbo.Resource AS A + WHERE IsHistory = 0 + AND EXISTS (SELECT * + FROM @Resources AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId); + SET @Rows = @@rowcount; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ResourceWriteClaim AS B + ON B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ReferenceSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenText AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.StringSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.UriSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.NumberSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.QuantitySearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.DateTimeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ReferenceTokenCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenTokenCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenDateTimeCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenQuantityCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenStringCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenNumberNumberCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM @ResourceWriteClaims; + INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceId, + ReferenceResourceVersion + FROM @ReferenceSearchParams; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM @TokenSearchParams; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM @TokenTexts; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM @StringSearchParams; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM @UriSearchParams; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM @NumberSearchParams; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM @QuantitySearchParams; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM @DateTimeSearchParams; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM @TokenTokenCompositeSearchParams; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM @TokenQuantityCompositeSearchParams; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM @TokenStringCompositeSearchParams; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM @TokenNumberNumberCompositeSearchParams; + COMMIT TRANSACTION; + SET @FailedResources = (SELECT count(*) + FROM @Resources) - @Rows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.UpsertSearchParams +@searchParams dbo.SearchParamTableType_2 READONLY +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; +BEGIN TRANSACTION; +DECLARE @lastUpdated AS DATETIMEOFFSET (7) = SYSDATETIMEOFFSET(); +DECLARE @summaryOfChanges TABLE ( + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Action VARCHAR (20) NOT NULL); +MERGE INTO dbo.SearchParam WITH (TABLOCKX) + AS target +USING @searchParams AS source ON target.Uri = source.Uri +WHEN MATCHED THEN UPDATE +SET Status = source.Status, + LastUpdated = @lastUpdated, + IsPartiallySupported = source.IsPartiallySupported +WHEN NOT MATCHED BY TARGET THEN INSERT (Uri, Status, LastUpdated, IsPartiallySupported) VALUES (source.Uri, source.Status, @lastUpdated, source.IsPartiallySupported) +OUTPUT source.Uri, $ACTION INTO @summaryOfChanges; +SELECT SearchParamId, + SearchParam.Uri +FROM dbo.SearchParam AS searchParam + INNER JOIN + @summaryOfChanges AS upsertedSearchParam + ON searchParam.Uri = upsertedSearchParam.Uri +WHERE upsertedSearchParam.Action = 'INSERT'; +COMMIT TRANSACTION; + +GO +CREATE VIEW dbo.Resource +AS +SELECT ResourceTypeId, + ResourceSurrogateId, + ResourceId, + Version, + IsHistory, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId +FROM dbo.ResourceHistory +UNION ALL +SELECT ResourceTypeId, + ResourceSurrogateId, + ResourceId, + Version, + IsHistory, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId +FROM dbo.ResourceCurrent; + + +GO +CREATE TRIGGER dbo.ResourceIns + ON dbo.Resource + INSTEAD OF INSERT + AS BEGIN + INSERT INTO dbo.RawResources (ResourceTypeId, ResourceSurrogateId, RawResource) + SELECT ResourceTypeId, + ResourceSurrogateId, + RawResource + FROM Inserted; + INSERT INTO dbo.ResourceCurrentTbl (ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId) + SELECT ResourceTypeId, + ResourceSurrogateId, + ResourceId, + Version, + IsDeleted, + RequestMethod, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId + FROM Inserted + WHERE IsHistory = 0; + INSERT INTO dbo.ResourceHistoryTbl (ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId) + SELECT ResourceTypeId, + ResourceSurrogateId, + ResourceId, + Version, + IsDeleted, + RequestMethod, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId + FROM Inserted + WHERE IsHistory = 1; + END + + +GO +CREATE TRIGGER dbo.ResourceUpd + ON dbo.Resource + INSTEAD OF UPDATE + AS BEGIN + IF UPDATE (IsDeleted) + AND UPDATE (RawResource) + AND UPDATE (SearchParamHash) + AND UPDATE (HistoryTransactionId) + AND NOT UPDATE (IsHistory) + BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted AS A + INNER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + UPDATE B + SET IsDeleted = A.IsDeleted, + SearchParamHash = A.SearchParamHash, + HistoryTransactionId = A.HistoryTransactionId + FROM Inserted AS A + INNER JOIN + dbo.ResourceCurrentTbl AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + RETURN; + END + IF UPDATE (SearchParamHash) + AND NOT UPDATE (IsHistory) + BEGIN + UPDATE B + SET SearchParamHash = A.SearchParamHash + FROM Inserted AS A + INNER JOIN + dbo.ResourceCurrentTbl AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE A.IsHistory = 0; + RETURN; + END + IF UPDATE (RawResource) + UPDATE B + SET RawResource = A.RawResource + FROM Inserted AS A + INNER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + IF NOT UPDATE (IsHistory) + RAISERROR ('Generic updates are not supported via Resource view', 18, 127); + DELETE A + FROM dbo.ResourceCurrentTbl AS A + WHERE EXISTS (SELECT * + FROM Inserted AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + AND B.IsHistory = 1); + INSERT INTO dbo.ResourceHistoryTbl (ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId) + SELECT ResourceTypeId, + ResourceSurrogateId, + ResourceId, + Version, + IsDeleted, + RequestMethod, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId + FROM Inserted + WHERE IsHistory = 1; + END + + +GO +CREATE TRIGGER dbo.ResourceDel + ON dbo.Resource + INSTEAD OF DELETE + AS BEGIN + DELETE A + FROM dbo.ResourceCurrentTbl AS A + WHERE EXISTS (SELECT * + FROM Deleted AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + AND B.IsHistory = 0); + DELETE A + FROM dbo.ResourceHistoryTbl AS A + WHERE EXISTS (SELECT * + FROM Deleted AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + AND B.IsHistory = 1); + DELETE A + FROM dbo.RawResources AS A + WHERE EXISTS (SELECT * + FROM Deleted AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId); + END + +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs index 309a6ff48d..e633808e9d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs @@ -93,5 +93,6 @@ public enum SchemaVersion V81 = 81, V82 = 82, V83 = 83, + V84 = 84, } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs index 17593e9b0f..0093ce5811 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs @@ -8,7 +8,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema public static class SchemaVersionConstants { public const int Min = (int)SchemaVersion.V80; - public const int Max = (int)SchemaVersion.V83; + public const int Max = (int)SchemaVersion.V84; public const int MinForUpgrade = (int)SchemaVersion.V80; // this is used for upgrade tests only public const int SearchParameterStatusSchemaVersion = (int)SchemaVersion.V6; public const int SupportForReferencesWithMissingTypeVersion = (int)SchemaVersion.V7; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql index df6c3891df..4e8bc838ee 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql @@ -19,6 +19,6 @@ Go INSERT INTO dbo.SchemaVersion VALUES - (83, 'started') + (84, 'started') Go diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql index 776ed1ac45..eae8002cf7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql @@ -39,7 +39,7 @@ BEGIN TRY WHERE NOT EXISTS (SELECT * FROM dbo.IndexProperties WHERE TableName = Tbl AND IndexName = Ind) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='IndexProperties',@Action='Insert',@Rows=@@rowcount - DELETE FROM @Indexes WHERE Tbl = 'Resource' OR IndId = 1 + DELETE FROM @Indexes WHERE Tbl IN ('Resource','ResourceCurrent','ResourceHistory') OR IndId = 1 EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Delete',@Rows=@@rowcount WHILE EXISTS (SELECT * FROM @Indexes) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index b9eb179a76..5f15482795 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -29,7 +29,7 @@ BEGIN TRY ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) ELSE SELECT * @@ -43,7 +43,7 @@ BEGIN TRY ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId @@ -55,7 +55,7 @@ BEGIN TRY ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 ) A OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) @@ -70,7 +70,7 @@ BEGIN TRY ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) @@ -83,5 +83,5 @@ BEGIN CATCH END CATCH GO --DECLARE @ResourceKeys dbo.ResourceKeyList ---INSERT INTO @ResourceKeys SELECT TOP 1 ResourceTypeId, ResourceId, NULL FROM Resource +--INSERT INTO @ResourceKeys SELECT 96, newid(), NULL --EXECUTE dbo.GetResources @ResourceKeys diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index d6e4ca76ed..eb6362f387 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -411,7 +411,7 @@ BEGIN CATCH EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.Resource''%' + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.RawResources''%') -- handles old and separated tables THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; ELSE THROW diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql index 88f4c2bfdf..1ba19733c9 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql @@ -29,11 +29,12 @@ BEGIN TRY BEGIN TRANSACTION -- Update the search parameter hash value in the main resource table - UPDATE B - SET SearchParamHash = A.SearchParamHash - OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids - FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - WHERE B.IsHistory = 0 + -- Avoid join to enable update via view + UPDATE A + SET SearchParamHash = (SELECT SearchParamHash FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) + FROM dbo.Resource A + WHERE IsHistory = 0 + AND EXISTS (SELECT * FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) SET @Rows = @@rowcount -- First, delete all the search params of the resources to reindex. diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql index e880a6b995..3298fbe159 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql @@ -1,52 +1,104 @@ -CREATE TABLE dbo.Resource +CREATE TABLE dbo.RawResources ( - ResourceTypeId smallint NOT NULL, - ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL, - Version int NOT NULL, - IsHistory bit NOT NULL, - ResourceSurrogateId bigint NOT NULL, - IsDeleted bit NOT NULL, - RequestMethod varchar(10) NULL, - RawResource varbinary(max) NOT NULL, - IsRawResourceMetaSet bit NOT NULL DEFAULT 0, - SearchParamHash varchar(64) NULL, - TransactionId bigint NULL, -- used for main CRUD operation - HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state - - CONSTRAINT PKC_Resource PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId(ResourceTypeId), - CONSTRAINT CH_Resource_RawResource_Length CHECK (RawResource > 0x0) -) - -ALTER TABLE dbo.Resource SET ( LOCK_ESCALATION = AUTO ) - -CREATE INDEX IX_ResourceTypeId_TransactionId ON dbo.Resource (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE INDEX IX_ResourceTypeId_HistoryTransactionId ON dbo.Resource (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,RawResource varbinary(max) NULL -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId_Version ON dbo.Resource -( - ResourceTypeId, - ResourceId, - Version + CONSTRAINT PKC_RawResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) -ON PartitionScheme_ResourceTypeId(ResourceTypeId) -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId ON dbo.Resource -( - ResourceTypeId, - ResourceId -) -INCLUDE -- We want the query in UpsertResource, which is done with UPDLOCK AND HOLDLOCK, to not require a key lookup +ALTER TABLE dbo.RawResources SET ( LOCK_ESCALATION = AUTO ) +GO +CREATE TABLE dbo.ResourceCurrent ( - Version, - IsDeleted + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,Version int NOT NULL + ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL -- used for main CRUD operation + ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state + + CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceId UNIQUE (ResourceTypeId, ResourceId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) -WHERE IsHistory = 0 -ON PartitionScheme_ResourceTypeId(ResourceTypeId) -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId ON dbo.Resource +ALTER TABLE dbo.ResourceCurrent SET ( LOCK_ESCALATION = AUTO ) + +-- Strictly speaking, IsHistory=0 filter in the index is not required because table has check constraint. +-- But SQL Server has a bug. For queries having IsHistory=0 in WHERE, SQL knows that only current table should be looked at. +-- But when choosing indexes it forgets about this unless IsHistory=0 is also included in index definition. +-- Without this redundant filtering clause in the index SQL chooses clustered index scan. For large tables it is a difference between running OK and timing out. +--CREATE UNIQUE INDEX IXU_ResourceTypeId_ResourceSurrogateId_WHERE_IsHistory_0_IsDeleted_0 ON dbo.ResourceCurrent (ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 AND IsDeleted = 0 WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +GO +EXECUTE sp_rename 'ResourceCurrent', 'ResourceCurrentTbl' +GO +CREATE VIEW dbo.ResourceCurrent +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,B.RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + FROM dbo.ResourceCurrentTbl A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId +GO +CREATE TABLE dbo.ResourceHistory ( - ResourceTypeId, - ResourceSurrogateId + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,Version int NOT NULL + ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1, CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1) + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL -- used for main CRUD operation + ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state + + CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) -WHERE IsHistory = 0 AND IsDeleted = 0 -ON PartitionScheme_ResourceTypeId(ResourceTypeId) + +ALTER TABLE dbo.ResourceHistory SET ( LOCK_ESCALATION = AUTO ) + +CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +GO +EXECUTE sp_rename 'ResourceHistory', 'ResourceHistoryTbl' +GO +CREATE VIEW dbo.ResourceHistory +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,B.RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + FROM dbo.ResourceHistoryTbl A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId +GO +CREATE TABLE dbo.Dummy (Dummy int) +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql new file mode 100644 index 0000000000..ec0d99b472 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -0,0 +1,119 @@ +CREATE VIEW dbo.Resource +AS +SELECT ResourceTypeId + ,ResourceSurrogateId + ,ResourceId + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + FROM dbo.ResourceHistory +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,ResourceId + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + FROM dbo.ResourceCurrent +GO +CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT +AS +BEGIN + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + + INSERT INTO dbo.ResourceCurrentTbl + ( ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId + FROM Inserted + WHERE IsHistory = 0 + + INSERT INTO dbo.ResourceHistoryTbl + ( ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId + FROM Inserted + WHERE IsHistory = 1 +END +GO +CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE +AS +BEGIN + IF UPDATE(IsDeleted) AND UPDATE(RawResource) AND UPDATE(SearchParamHash) AND UPDATE(HistoryTransactionId) AND NOT UPDATE(IsHistory) -- HardDeleteResource + BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted A + JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + UPDATE B + SET IsDeleted = A.IsDeleted + ,SearchParamHash = A.SearchParamHash + ,HistoryTransactionId = A.HistoryTransactionId + FROM Inserted A + JOIN dbo.ResourceCurrentTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + RETURN + END + + IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) + BEGIN + UPDATE B + SET SearchParamHash = A.SearchParamHash + FROM Inserted A + JOIN dbo.ResourceCurrentTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE A.IsHistory = 0 + + RETURN + END + + IF UPDATE(RawResource) -- invisible records + UPDATE B + SET RawResource = A.RawResource + FROM Inserted A + JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + IF NOT UPDATE(IsHistory) + RAISERROR('Generic updates are not supported via Resource view',18,127) + + DELETE FROM A + FROM dbo.ResourceCurrentTbl A + WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) + + INSERT INTO dbo.ResourceHistoryTbl + ( ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId + FROM Inserted + WHERE IsHistory = 1 +END +GO +CREATE TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE +AS +BEGIN + DELETE FROM A + FROM dbo.ResourceCurrentTbl A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) + + DELETE FROM A + FROM dbo.ResourceHistoryTbl A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) + + DELETE FROM A + FROM dbo.RawResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs index 859c8fe83c..897fc9f55d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs @@ -24,9 +24,9 @@ public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpressio context.StringBuilder.AppendLine("("); using (context.StringBuilder.Indent()) { - VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.Resource.ResourceTypeId, null, primaryKeyRange.CurrentValue.ResourceTypeId, includeInParameterHash: false); + VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.ResourceCurrent.ResourceTypeId, null, primaryKeyRange.CurrentValue.ResourceTypeId, includeInParameterHash: false); context.StringBuilder.Append(" AND "); - VisitSimpleBinary(expression.BinaryOperator, context, VLatest.Resource.ResourceSurrogateId, null, primaryKeyRange.CurrentValue.ResourceSurrogateId, includeInParameterHash: false); + VisitSimpleBinary(expression.BinaryOperator, context, VLatest.ResourceCurrent.ResourceSurrogateId, null, primaryKeyRange.CurrentValue.ResourceSurrogateId, includeInParameterHash: false); bool first = true; for (short i = 0; i < primaryKeyRange.NextResourceTypeIds.Count; i++) @@ -37,7 +37,7 @@ public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpressio { context.StringBuilder.AppendLine(); context.StringBuilder.Append("OR "); - AppendColumnName(context, VLatest.Resource.ResourceTypeId, (int?)null).Append(" IN ("); + AppendColumnName(context, VLatest.ResourceCurrent.ResourceTypeId, (int?)null).Append(" IN ("); first = false; } else @@ -45,7 +45,7 @@ public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpressio context.StringBuilder.Append(", "); } - context.StringBuilder.Append(context.Parameters.AddParameter(VLatest.Resource.ResourceTypeId, i, includeInHash: false)); + context.StringBuilder.Append(context.Parameters.AddParameter(VLatest.ResourceCurrent.ResourceTypeId, i, includeInHash: false)); } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs index acdfadbbb6..73ad6d4f55 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs @@ -14,7 +14,7 @@ internal class ResourceIdParameterQueryGenerator : ResourceTableSearchParameterQ public override SearchParameterQueryGeneratorContext VisitString(StringExpression expression, SearchParameterQueryGeneratorContext context) { - VisitSimpleString(expression, context, VLatest.Resource.ResourceId, expression.Value); + VisitSimpleString(expression, context, VLatest.ResourceCurrent.ResourceId, expression.Value); return context; } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs index 9f3c700a19..4d7ea9863e 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs @@ -14,7 +14,7 @@ internal class ResourceSurrogateIdParameterQueryGenerator : ResourceTableSearchP public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpression expression, SearchParameterQueryGeneratorContext context) { - VisitSimpleBinary(expression.BinaryOperator, context, VLatest.Resource.ResourceSurrogateId, expression.ComponentIndex, expression.Value, includeInParameterHash: false); + VisitSimpleBinary(expression.BinaryOperator, context, VLatest.ResourceCurrent.ResourceSurrogateId, expression.ComponentIndex, expression.Value, includeInParameterHash: false); return context; } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs index 93527ebe1b..515099aac3 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs @@ -22,7 +22,7 @@ public override SearchParameterQueryGeneratorContext VisitString(StringExpressio return context; } - return VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.Resource.ResourceTypeId, expression.ComponentIndex, resourceTypeId); + return VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.ResourceCurrent.ResourceTypeId, expression.ComponentIndex, resourceTypeId); } public override SearchParameterQueryGeneratorContext VisitIn(InExpression expression, SearchParameterQueryGeneratorContext context) @@ -41,7 +41,7 @@ public override SearchParameterQueryGeneratorContext VisitIn(InExpression } } - return VisitSimpleIn(context, VLatest.Resource.ResourceTypeId, resolvedResourceTypeIds); + return VisitSimpleIn(context, VLatest.ResourceCurrent.ResourceTypeId, resolvedResourceTypeIds); } } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index e229ae7239..10509800cf 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -14,7 +14,6 @@ using Microsoft.Health.Fhir.Core.Features.Search; using Microsoft.Health.Fhir.Core.Features.Search.Expressions; using Microsoft.Health.Fhir.Core.Models; -using Microsoft.Health.Fhir.SqlServer.Features.Schema; using Microsoft.Health.Fhir.SqlServer.Features.Schema.Model; using Microsoft.Health.Fhir.SqlServer.Features.Storage; using Microsoft.Health.SqlServer; @@ -188,25 +187,22 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions StringBuilder.Append("TOP (").Append(Parameters.AddParameter(context.MaxItemCount + 1, includeInHash: false)).Append(") "); } - StringBuilder.Append(VLatest.Resource.ResourceTypeId, resourceTableAlias).Append(", ") - .Append(VLatest.Resource.ResourceId, resourceTableAlias).Append(", ") - .Append(VLatest.Resource.Version, resourceTableAlias).Append(", ") - .Append(VLatest.Resource.IsDeleted, resourceTableAlias).Append(", ") - .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).Append(", ") - .Append(VLatest.Resource.RequestMethod, resourceTableAlias).Append(", "); + StringBuilder.Append(VLatest.ResourceCurrent.ResourceTypeId, resourceTableAlias).Append(", ") + .Append(VLatest.ResourceCurrent.ResourceId, resourceTableAlias).Append(", ") + .Append(VLatest.ResourceCurrent.Version, resourceTableAlias).Append(", ") + .Append(VLatest.ResourceCurrent.IsDeleted, resourceTableAlias).Append(", ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).Append(", ") + .Append(VLatest.ResourceCurrent.RequestMethod, resourceTableAlias).Append(", "); // If there's a table expression, use the previously selected bit, otherwise everything in the select is considered a match StringBuilder.Append(expression.SearchParamTableExpressions.Count > 0 ? "CAST(IsMatch AS bit) AS IsMatch, " : "CAST(1 AS bit) AS IsMatch, "); StringBuilder.Append(expression.SearchParamTableExpressions.Count > 0 ? "CAST(IsPartial AS bit) AS IsPartial, " : "CAST(0 AS bit) AS IsPartial, "); - StringBuilder.Append(VLatest.Resource.IsRawResourceMetaSet, resourceTableAlias).Append(", "); + StringBuilder.Append(VLatest.ResourceCurrent.IsRawResourceMetaSet, resourceTableAlias).Append(", "); - if (_schemaInfo.Current >= SchemaVersionConstants.SearchParameterHashSchemaVersion) - { - StringBuilder.Append(VLatest.Resource.SearchParamHash, resourceTableAlias).Append(", "); - } + StringBuilder.Append(VLatest.ResourceCurrent.SearchParamHash, resourceTableAlias).Append(", "); - StringBuilder.Append(VLatest.Resource.RawResource, resourceTableAlias); + StringBuilder.Append(VLatest.ResourceCurrent.RawResource, resourceTableAlias); if (IsSortValueNeeded(context)) { @@ -218,29 +214,14 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions if (selectingFromResourceTable) { - StringBuilder.Append("FROM ").Append(VLatest.Resource).Append(" ").Append(resourceTableAlias); - - if (expression.SearchParamTableExpressions.Count == 0 && - !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) && - !context.ResourceVersionTypes.HasFlag(ResourceVersionType.SoftDeleted) && - expression.ResourceTableExpressions.Any(e => e.AcceptVisitor(ExpressionContainsParameterVisitor.Instance, SearchParameterNames.ResourceType)) && - !expression.ResourceTableExpressions.Any(e => e.AcceptVisitor(ExpressionContainsParameterVisitor.Instance, SearchParameterNames.Id))) - { - // If this is a simple search over a resource type (like GET /Observation) - // make sure the optimizer does not decide to do a scan on the clustered index, since we have an index specifically for this common case - StringBuilder.Append(" WITH (INDEX(").Append(VLatest.Resource.IX_Resource_ResourceTypeId_ResourceSurrgateId).AppendLine("))"); - } - else - { - StringBuilder.AppendLine(); - } + StringBuilder.Append("FROM ").Append(VLatest.ResourceCurrent).Append(" ").AppendLine(resourceTableAlias); if (expression.SearchParamTableExpressions.Count > 0) { StringBuilder.Append(_joinShift).Append("JOIN ").Append(TableExpressionName(_tableExpressionCounter)); StringBuilder.Append(" ON ") - .Append(VLatest.Resource.ResourceTypeId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).Append(".T1 AND ") - .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).AppendLine(".Sid1"); + .Append(VLatest.ResourceCurrent.ResourceTypeId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).Append(".T1 AND ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).AppendLine(".Sid1"); } using (var delimitedClause = StringBuilder.BeginDelimitedWhereClause()) @@ -269,15 +250,15 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions if (IsPrimaryKeySort(searchOptions)) { StringBuilder.AppendDelimited(", ", searchOptions.Sort, (sb, sort) => - { - Column column = sort.searchParameterInfo.Name switch { - SearchParameterNames.ResourceType => VLatest.Resource.ResourceTypeId, - SearchParameterNames.LastUpdated => VLatest.Resource.ResourceSurrogateId, - _ => throw new InvalidOperationException($"Unexpected sort parameter {sort.searchParameterInfo.Name}"), - }; - sb.Append(column, resourceTableAlias).Append(" ").Append(sort.sortOrder == SortOrder.Ascending ? "ASC" : "DESC"); - }) + Column column = sort.searchParameterInfo.Name switch + { + SearchParameterNames.ResourceType => VLatest.ResourceCurrent.ResourceTypeId, + SearchParameterNames.LastUpdated => VLatest.ResourceCurrent.ResourceSurrogateId, + _ => throw new InvalidOperationException($"Unexpected sort parameter {sort.searchParameterInfo.Name}"), + }; + sb.Append(column, resourceTableAlias).Append(" ").Append(sort.sortOrder == SortOrder.Ascending ? "ASC" : "DESC"); + }) .AppendLine(); } else if (IsSortValueNeeded(searchOptions)) @@ -286,12 +267,12 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions .Append(TableExpressionName(_tableExpressionCounter)) .Append(".SortValue ") .Append(searchOptions.Sort[0].sortOrder == SortOrder.Ascending ? "ASC" : "DESC").Append(", ") - .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); } else { StringBuilder - .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); } AddOptionClause(); @@ -421,8 +402,8 @@ private void HandleParamTableUnion(SearchParamTableExpression searchParamTableEx StringBuilder.Append(TableExpressionName(++_tableExpressionCounter)).AppendLine(" AS").AppendLine("("); StringBuilder.Append("SELECT ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1"); + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1"); var searchParameterExpressionPredicate = searchParamTableExpression.Predicate as SearchParameterExpression; @@ -430,7 +411,7 @@ private void HandleParamTableUnion(SearchParamTableExpression searchParamTableEx if (searchParameterExpressionPredicate != null && searchParameterExpressionPredicate.Parameter.ColumnLocation().HasFlag(SearchParameterColumnLocation.ResourceTable)) { - StringBuilder.Append("FROM ").AppendLine(new VLatest.ResourceTable()); + StringBuilder.Append("FROM ").AppendLine(new VLatest.ResourceCurrentTable()); } else { @@ -461,8 +442,8 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx if (!IsInSortMode(context) || predecessorIndex < 0) { StringBuilder.Append("SELECT ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); } else @@ -470,13 +451,13 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx // we are in sort mode and we need to join with previous cte to propagate the SortValue var cte = TableExpressionName(predecessorIndex); StringBuilder.Append("SELECT ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).Append(" AS Sid1, ") + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" AS Sid1, ") .Append(cte).AppendLine(".SortValue") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table) .Append(_joinShift).Append("JOIN ").Append(cte) - .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); + .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); } } else if (searchParamTableExpression.ChainLevel == 1 && _unionVisited) @@ -488,16 +469,16 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx if (searchParameterExpressionPredicate != null && searchParameterExpressionPredicate.Parameter.ColumnLocation().HasFlag(SearchParameterColumnLocation.ResourceTable)) { - tableName = new VLatest.ResourceTable(); + tableName = new VLatest.ResourceCurrentTable(); } StringBuilder.Append("SELECT T1, Sid1, ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T2, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid2") + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T2, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid2") .Append("FROM ").AppendLine(tableName) .Append(_joinShift).Append("JOIN ").Append(TableExpressionName(FindRestrictingPredecessorTableExpressionIndex())) - .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(_firstChainAfterUnionVisited ? "T2" : "T1") - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").AppendLine(_firstChainAfterUnionVisited ? "Sid2" : "Sid1"); + .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append(_firstChainAfterUnionVisited ? "T2" : "T1") + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").AppendLine(_firstChainAfterUnionVisited ? "Sid2" : "Sid1"); // once we have visited a table after the union all, the remained of the inner joins // should be on T1 and Sid1 @@ -506,12 +487,12 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx else { StringBuilder.Append("SELECT T1, Sid1, ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T2, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid2") + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T2, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid2") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table) .Append(_joinShift).Append("JOIN ").Append(TableExpressionName(FindRestrictingPredecessorTableExpressionIndex())) - .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append("T2") - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").AppendLine("Sid2"); + .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append("T2") + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").AppendLine("Sid2"); } if (UseAppendWithJoin() @@ -549,12 +530,12 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre { var cte = TableExpressionName(predecessorIndex); StringBuilder.Append("SELECT ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") // SELECT and FROM can be on same line only for singe line statements - .Append("FROM ").AppendLine(VLatest.Resource) + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1") // SELECT and FROM can be on same line only for singe line statements + .Append("FROM ").AppendLine(VLatest.ResourceCurrent) .Append(_joinShift).Append("JOIN ").Append(cte) - .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); + .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -570,9 +551,9 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre else { StringBuilder.Append("SELECT ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") - .Append("FROM ").AppendLine(VLatest.Resource); + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1") + .Append("FROM ").AppendLine(VLatest.ResourceCurrent); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -596,7 +577,7 @@ private void HandleTableKindNotExists(SearchParamTableExpression searchParamTabl using (StringBuilder.Indent()) { - StringBuilder.Append("SELECT ").AppendLine(VLatest.Resource.ResourceSurrogateId, null) + StringBuilder.Append("SELECT ").AppendLine(VLatest.ResourceCurrent.ResourceSurrogateId, null) .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -695,21 +676,21 @@ private void HandleTableKindChain( } StringBuilder - .Append(VLatest.Resource.ResourceTypeId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").Append(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "T1, " : "T2, ") - .Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") + .Append(VLatest.ResourceCurrent.ResourceTypeId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").Append(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "T1, " : "T2, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") .Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) - .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) - .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); + .Append(_joinShift).Append("JOIN ").Append(VLatest.ResourceCurrent).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceTargetResourceTableAlias) + .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.ResourceCurrent.ResourceId, referenceTargetResourceTableAlias); // For reverse chaining, if there is a parameter on the _id search parameter, we need another join to get the resource ID of the reference source (all we have is the surrogate ID at this point) bool expressionOnTargetHandledBySecondJoin = chainedExpression.ExpressionOnTarget != null && chainedExpression.Reversed && chainedExpression.ExpressionOnTarget.AcceptVisitor(ExpressionContainsParameterVisitor.Instance, SearchParameterNames.Id); if (expressionOnTargetHandledBySecondJoin) { const string referenceSourceResourceTableAlias = "refSourceResource"; - StringBuilder.Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) - .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceSourceResourceTableAlias) - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceResourceTableAlias) + StringBuilder.Append(_joinShift).Append("JOIN ").Append(VLatest.ResourceCurrent).Append(' ').Append(referenceSourceResourceTableAlias) + .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceSourceResourceTableAlias) + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, referenceSourceResourceTableAlias) .Append(" AND "); chainedExpression.ExpressionOnTarget.AcceptVisitor(ResourceTableSearchParameterQueryGenerator.Instance, GetContext(referenceSourceResourceTableAlias)); StringBuilder.AppendLine(); @@ -718,8 +699,8 @@ private void HandleTableKindChain( if (searchParamTableExpression.ChainLevel > 1) { StringBuilder.Append(_joinShift).Append("JOIN ").Append(TableExpressionName(FindRestrictingPredecessorTableExpressionIndex())) - .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").Append("T2") - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").AppendLine("Sid2"); + .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").Append("T2") + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").AppendLine("Sid2"); } // since we are in chain table expression, we know the Table is the ReferenceSearchParam table @@ -790,14 +771,14 @@ private void HandleTableKindInclude( var table = !includeExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias; - StringBuilder.Append(VLatest.Resource.ResourceTypeId, table).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, table) + StringBuilder.Append(VLatest.ResourceCurrent.ResourceTypeId, table).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, table) .AppendLine(" AS Sid1, 0 AS IsMatch "); StringBuilder.Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) - .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) - .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); + .Append(_joinShift).Append("JOIN ").Append(VLatest.ResourceCurrent).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceTargetResourceTableAlias) + .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.ResourceCurrent.ResourceId, referenceTargetResourceTableAlias); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -896,8 +877,8 @@ private void HandleTableKindInclude( } delimited.BeginDelimitedElement().Append("EXISTS (SELECT * FROM ").Append(fromCte) - .Append(" WHERE ").Append(VLatest.Resource.ResourceTypeId, table).Append(" = T1 AND ") - .Append(VLatest.Resource.ResourceSurrogateId, table).Append(" = Sid1"); + .Append(" WHERE ").Append(VLatest.ResourceCurrent.ResourceTypeId, table).Append(" = T1 AND ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, table).Append(" = Sid1"); if (!includeExpression.Iterate) { @@ -1050,8 +1031,8 @@ private void HandleTableKindSort(SearchParamTableExpression searchParamTableExpr if (!string.IsNullOrEmpty(sortContext.SortColumnName) && searchParamTableExpression.QueryGenerator != null) { StringBuilder.Append("SELECT ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).Append(" AS Sid1, ") + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" AS Sid1, ") .Append(sortContext.SortColumnName, null).AppendLine(" AS SortValue") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); @@ -1078,7 +1059,7 @@ private void HandleTableKindSort(SearchParamTableExpression searchParamTableExpr delimited.BeginDelimitedElement(); StringBuilder.Append("((").Append(sortContext.SortColumnName, null).Append(" = ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)); - StringBuilder.Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.Resource.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); + StringBuilder.Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.ResourceCurrent.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); StringBuilder.Append(" OR ").Append(sortContext.SortColumnName, null).Append(" ").Append(sortOperand).Append(" ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)).AppendLine(")"); } @@ -1099,8 +1080,8 @@ private void HandleTableKindSortWithFilter(SearchParamTableExpression searchPara if (!string.IsNullOrEmpty(sortContext.SortColumnName) && searchParamTableExpression.QueryGenerator != null) { StringBuilder.Append("SELECT ") - .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.Resource.ResourceSurrogateId, null).Append(" AS Sid1, ") + .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" AS Sid1, ") .Append(sortContext.SortColumnName, null).AppendLine(" AS SortValue") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); @@ -1127,7 +1108,7 @@ private void HandleTableKindSortWithFilter(SearchParamTableExpression searchPara delimited.BeginDelimitedElement(); StringBuilder.Append("((").Append(sortContext.SortColumnName, null).Append(" = ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)); - StringBuilder.Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.Resource.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); + StringBuilder.Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.ResourceCurrent.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); StringBuilder.Append(" OR ").Append(sortContext.SortColumnName, null).Append(" ").Append(sortOperand).Append(" ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)).AppendLine(")"); } @@ -1245,8 +1226,8 @@ private void AppendIntersectionWithPredecessor(IndentedStringBuilder.DelimitedSc bool intersectWithFirst = (searchParamTableExpression.Kind == SearchParamTableExpressionKind.Chain ? searchParamTableExpression.ChainLevel - 1 : searchParamTableExpression.ChainLevel) == 0; StringBuilder.Append("EXISTS (SELECT * FROM ").Append(TableExpressionName(predecessorIndex)) - .Append(" WHERE ").Append(VLatest.Resource.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") + .Append(" WHERE ").Append(VLatest.ResourceCurrent.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") .Append(')'); } } @@ -1263,8 +1244,8 @@ private void AppendIntersectionWithPredecessorUsingInnerJoin(IndentedStringBuild // rather than an EXISTS clause. We have see that this significanlty reduces the query plan generation time for // complex queries sb.Append(_joinShift).Append("JOIN " + TableExpressionName(predecessorIndex - 0)) - .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") - .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") + .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") + .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") .AppendLine(); } } @@ -1315,12 +1296,12 @@ private void AppendDeletedClause(in IndentedStringBuilder.DelimitedScope delimit if (resourceVersionType.HasFlag(ResourceVersionType.Latest) && !resourceVersionType.HasFlag(ResourceVersionType.SoftDeleted)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.Resource.IsDeleted, tableAlias).Append(" = 0 "); + StringBuilder.Append(VLatest.ResourceCurrent.IsDeleted, tableAlias).Append(" = 0 "); } else if (resourceVersionType.HasFlag(ResourceVersionType.SoftDeleted) && !resourceVersionType.HasFlag(ResourceVersionType.Latest)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.Resource.IsDeleted, tableAlias).Append(" = 1 "); + StringBuilder.Append(VLatest.ResourceCurrent.IsDeleted, tableAlias).Append(" = 1 "); } } @@ -1334,22 +1315,17 @@ private void AppendHistoryClause(in IndentedStringBuilder.DelimitedScope delimit if (resourceVersionType.HasFlag(ResourceVersionType.Latest) && !resourceVersionType.HasFlag(ResourceVersionType.History)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.Resource.IsHistory, tableAlias).Append(" = 0 "); + StringBuilder.Append(VLatest.ResourceCurrent.IsHistory, tableAlias).Append(" = 0 "); } else if (resourceVersionType.HasFlag(ResourceVersionType.History) && !resourceVersionType.HasFlag(ResourceVersionType.Latest)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.Resource.IsHistory, tableAlias).Append(" = 1 "); + StringBuilder.Append(VLatest.ResourceCurrent.IsHistory, tableAlias).Append(" = 1 "); } } private void AppendMinOrMax(in IndentedStringBuilder.DelimitedScope delimited, SearchOptions context) { - if (_schemaInfo.Current < SchemaVersionConstants.AddMinMaxForDateAndStringSearchParamVersion) - { - return; - } - delimited.BeginDelimitedElement(); if (context.Sort[0].sortOrder == SortOrder.Ascending) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs index 46fbce6cc1..bebe4b1f26 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs @@ -63,7 +63,7 @@ public object AddParameter(Column column, T value, bool includeInHash) /// SQL parameter or input value depending on whether input was added to the list of parameters. public object AddParameter(Column column, object value, bool includeInHash) { - if (column.Metadata.Name == VLatest.Resource.ResourceTypeId.Metadata.Name // logic uses "ResourceTypeId" string value. Resource table is chosen arbitrarily. + if (column.Metadata.Name == VLatest.ResourceCurrent.ResourceTypeId.Metadata.Name // logic uses "ResourceTypeId" string value. Resource table is chosen arbitrarily. || column.Metadata.Name == VLatest.ReferenceSearchParam.ReferenceResourceTypeId.Metadata.Name || column.Metadata.Name == VLatest.TokenSearchParam.SearchParamId.Metadata.Name) // logic uses "SearchParamId" string value. We don't have cross table column sharing concept yet, so to avoid hardcoding TokenSearchParam is arbitrarily chosen. { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index dcc77f90f1..773414efa4 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -379,6 +379,9 @@ await _sqlRetryService.ExecuteSql( sqlCommand.CommandType = CommandType.StoredProcedure; } + // Put "union" view + queryText = queryText.Replace("dbo.ResourceCurrent", "dbo.Resource", StringComparison.InvariantCulture); + // Command text contains no direct user input. #pragma warning disable CA2100 // Review SQL queries for security vulnerabilities sqlCommand.CommandText = queryText; @@ -839,16 +842,16 @@ private void ReadWrapper( out byte[] rawResourceBytes, out bool isInvisible) { - resourceTypeId = reader.Read(VLatest.Resource.ResourceTypeId, 0); - resourceId = reader.Read(VLatest.Resource.ResourceId, 1); - version = reader.Read(VLatest.Resource.Version, 2); - isDeleted = reader.Read(VLatest.Resource.IsDeleted, 3); - resourceSurrogateId = reader.Read(VLatest.Resource.ResourceSurrogateId, 4); - requestMethod = reader.Read(VLatest.Resource.RequestMethod, 5); + resourceTypeId = reader.Read(VLatest.ResourceCurrent.ResourceTypeId, 0); + resourceId = reader.Read(VLatest.ResourceCurrent.ResourceId, 1); + version = reader.Read(VLatest.ResourceCurrent.Version, 2); + isDeleted = reader.Read(VLatest.ResourceCurrent.IsDeleted, 3); + resourceSurrogateId = reader.Read(VLatest.ResourceCurrent.ResourceSurrogateId, 4); + requestMethod = reader.Read(VLatest.ResourceCurrent.RequestMethod, 5); isMatch = reader.Read(_isMatch, 6); isPartialEntry = reader.Read(_isPartial, 7); - isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 8); - searchParameterHash = reader.Read(VLatest.Resource.SearchParamHash, 9); + isRawResourceMetaSet = reader.Read(VLatest.ResourceCurrent.IsRawResourceMetaSet, 8); + searchParameterHash = reader.Read(VLatest.ResourceCurrent.SearchParamHash, 9); rawResourceBytes = reader.GetSqlBytes(10).Value; isInvisible = rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF; } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 309656f327..1ace933560 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -101,7 +101,7 @@ public async Task> GetAsync(IReadOnlyList new ResourceDateKeyListRow(_.ResourceTypeId, _.Id, _.ResourceSurrogateId)); new ResourceDateKeyListTableValuedParameterDefinition("@ResourceDateKeys").AddParameter(cmd.Parameters, tvpRows); - var table = VLatest.Resource; + var table = VLatest.ResourceCurrent; var resources = await cmd.ExecuteReaderAsync( _sqlRetryService, (reader) => @@ -155,16 +155,16 @@ internal async Task> GetResourcesByTransactionIdA private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func decompress, Func getResourceTypeName) { - var resourceTypeId = reader.Read(VLatest.Resource.ResourceTypeId, 0); - var resourceId = reader.Read(VLatest.Resource.ResourceId, 1); - var resourceSurrogateId = reader.Read(VLatest.Resource.ResourceSurrogateId, 2); - var version = reader.Read(VLatest.Resource.Version, 3); - var isDeleted = reader.Read(VLatest.Resource.IsDeleted, 4); - var isHistory = reader.Read(VLatest.Resource.IsHistory, 5); + var resourceTypeId = reader.Read(VLatest.ResourceCurrent.ResourceTypeId, 0); + var resourceId = reader.Read(VLatest.ResourceCurrent.ResourceId, 1); + var resourceSurrogateId = reader.Read(VLatest.ResourceCurrent.ResourceSurrogateId, 2); + var version = reader.Read(VLatest.ResourceCurrent.Version, 3); + var isDeleted = reader.Read(VLatest.ResourceCurrent.IsDeleted, 4); + var isHistory = reader.Read(VLatest.ResourceCurrent.IsHistory, 5); var rawResource = ReadRawResource(reader, decompress, 6); - var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); - var searchParamHash = reader.Read(VLatest.Resource.SearchParamHash, 8); - var requestMethod = readRequestMethod ? reader.Read(VLatest.Resource.RequestMethod, 9) : null; + var isRawResourceMetaSet = reader.Read(VLatest.ResourceCurrent.IsRawResourceMetaSet, 7); + var searchParamHash = reader.Read(VLatest.ResourceCurrent.SearchParamHash, 8); + var requestMethod = readRequestMethod ? reader.Read(VLatest.ResourceCurrent.RequestMethod, 9) : null; return new ResourceWrapper( resourceId, version.ToString(CultureInfo.InvariantCulture), @@ -199,11 +199,11 @@ internal async Task MergeResourcesPutTransactionHeartbeatAsync(long transactionI private ResourceDateKey ReadResourceDateKeyWrapper(SqlDataReader reader) { - var resourceTypeId = reader.Read(VLatest.Resource.ResourceTypeId, 0); - var resourceId = reader.Read(VLatest.Resource.ResourceId, 1); - var resourceSurrogateId = reader.Read(VLatest.Resource.ResourceSurrogateId, 2); - var version = reader.Read(VLatest.Resource.Version, 3); - var isDeleted = reader.Read(VLatest.Resource.IsDeleted, 4); + var resourceTypeId = reader.Read(VLatest.ResourceCurrent.ResourceTypeId, 0); + var resourceId = reader.Read(VLatest.ResourceCurrent.ResourceId, 1); + var resourceSurrogateId = reader.Read(VLatest.ResourceCurrent.ResourceSurrogateId, 2); + var version = reader.Read(VLatest.ResourceCurrent.Version, 3); + var isDeleted = reader.Read(VLatest.ResourceCurrent.IsDeleted, 4); return new ResourceDateKey(resourceTypeId, resourceId, resourceSurrogateId, version.ToString(CultureInfo.InvariantCulture), isDeleted); } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj index c537d49285..909f001e89 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj +++ b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj @@ -1,7 +1,7 @@  - 83 + 84 Features\Schema\Migrations\$(LatestSchemaVersion).sql @@ -43,6 +43,7 @@ + diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/ChangeFeed/SqlServerFhirResourceChangeCaptureEnabledTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/ChangeFeed/SqlServerFhirResourceChangeCaptureEnabledTests.cs index d52007c1ff..062679e812 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/ChangeFeed/SqlServerFhirResourceChangeCaptureEnabledTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/ChangeFeed/SqlServerFhirResourceChangeCaptureEnabledTests.cs @@ -102,7 +102,7 @@ public async Task GivenADatabaseSupportsResourceChangeCapture_WhenUpdatingAResou [Fact] public async Task GivenADatabaseSupportsResourceChangeCapture_WhenImportingNegativeVersions_ThenResourceChangesShouldBeReturned() { - ExecuteSql("TRUNCATE TABLE dbo.Resource"); + ExecuteSql("DELETE FROM dbo.Resource"); var store = (SqlServerFhirDataStore)_fixture.DataStore; @@ -133,7 +133,7 @@ public async Task GivenChangeCaptureEnabledAndNoVersionPolicy_AfterUpdating_Invi { EnableInvisibleHistory(); ExecuteSql("TRUNCATE TABLE dbo.Transactions"); - ExecuteSql("TRUNCATE TABLE dbo.Resource"); + ExecuteSql("DELETE FROM dbo.Resource"); var store = (SqlServerFhirDataStore)_fixture.DataStore; @@ -181,7 +181,7 @@ public async Task GivenChangeCaptureEnabledAndNoVersionPolicy_AfterHardDeleting_ { EnableInvisibleHistory(); ExecuteSql("TRUNCATE TABLE dbo.Transactions"); - ExecuteSql("TRUNCATE TABLE dbo.Resource"); + ExecuteSql("DELETE FROM dbo.Resource"); var store = (SqlServerFhirDataStore)_fixture.DataStore; diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs index cc720869b7..e2d6833efb 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs @@ -75,7 +75,7 @@ public async Task ExportWorkRegistration() finally { ExecuteSql("TRUNCATE TABLE dbo.JobQueue"); - ExecuteSql("TRUNCATE TABLE dbo.Resource"); + ExecuteSql("DELETE FROM dbo.Resource"); ExecuteSql(DropTrigger); } } @@ -151,7 +151,7 @@ FOR INSERT private void PrepareData() { ExecuteSql("TRUNCATE TABLE dbo.JobQueue"); - ExecuteSql("TRUNCATE TABLE dbo.Resource"); + ExecuteSql("DELETE FROM dbo.Resource"); var surrId = DateTimeOffset.UtcNow.ToId(); ExecuteSql(@$" INSERT INTO Resource diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs index 8187afa22a..af7e4c7255 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs @@ -79,10 +79,10 @@ public async Task RetriesOnConflict(int requestedExceptions) { await _fixture.SqlHelper.ExecuteSqlCmd("TRUNCATE TABLE EventLog"); await _fixture.SqlHelper.ExecuteSqlCmd(@$" -CREATE TRIGGER Resource_Trigger ON Resource FOR INSERT +CREATE TRIGGER Resource_Trigger ON ResourceCurrentTbl FOR INSERT AS IF (SELECT count(*) FROM EventLog WHERE Process = 'MergeResources' AND Status = 'Error') < {requestedExceptions} - INSERT INTO Resource SELECT * FROM inserted -- this will cause dup key exception which is treated as a conflict + INSERT INTO ResourceCurrentTbl SELECT * FROM inserted -- this will cause dup key exception which is treated as a conflict "); var patient = (Patient)Samples.GetJsonSample("Patient").ToPoco(); @@ -204,7 +204,8 @@ private async Task UpdateResource(Patient patient) newId = Guid.NewGuid().ToString(); patient.Id = newId; await Mediator.UpsertResourceAsync(patient.ToResourceElement()); // there is no control to keep history, so insert as new and update to old - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET ResourceId = '{oldId}', Version = 3 WHERE ResourceId = '{newId}' AND Version = 1"); + //// noramlly we do not allow update in place + await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.ResourceCurrent SET ResourceId = '{oldId}', Version = 3 WHERE ResourceId = '{newId}' AND Version = 1"); } [Fact] diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs index f9ff1e61af..56e32d6723 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs @@ -301,10 +301,10 @@ async Task IFhirStorageTestHelper.ValidateSnapshotTokenIsCurrent(object snapshot await using (SqlCommand outerCommand = connection.CreateCommand()) { outerCommand.CommandText = @" - SELECT t.name - FROM sys.tables t - INNER JOIN sys.columns c ON c.object_id = t.object_id - WHERE c.name = 'ResourceSurrogateId'"; +SELECT t.name + FROM (SELECT name, object_id FROM sys.objects WHERE name NOT IN ('ResourceCurrent', 'ResourceHistory') AND type IN ('u','v')) t + JOIN sys.columns c ON c.object_id = t.object_id + WHERE c.name = 'ResourceSurrogateId'"; await using (SqlDataReader reader = await outerCommand.ExecuteReaderAsync()) { diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs index 6fb67f682d..cb77456dfd 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs @@ -296,8 +296,8 @@ private async Task CompareDatabaseSchemas(string databaseName1, string d if (schemaDifference.SourceObject != null && schemaDifference.TargetObject != null - && schemaDifference.SourceObject.ObjectType.Name == "Procedure" - && await IsStoredProcedureTextEqual(testConnectionString1, testConnectionString2, schemaDifference.SourceObject.Name.ToString())) + && (schemaDifference.SourceObject.ObjectType.Name == "Procedure" || schemaDifference.SourceObject.ObjectType.Name == "View") + && await IsObjectTextEqual(testConnectionString1, testConnectionString2, schemaDifference.SourceObject.Name.ToString())) { continue; } @@ -318,10 +318,10 @@ private async Task CompareDatabaseSchemas(string databaseName1, string d return unexpectedDifference.ToString(); } - private async Task IsStoredProcedureTextEqual(string connStr1, string connStr2, string storedProcedureName) + private async Task IsObjectTextEqual(string connStr1, string connStr2, string objectName) { - var text1 = await GetStoredProcedureText(connStr1, storedProcedureName); - var text2 = await GetStoredProcedureText(connStr2, storedProcedureName); + var text1 = await GetObjectText(connStr1, objectName); + var text2 = await GetObjectText(connStr2, objectName); text1 = Normalize(text1); text2 = Normalize(text2); @@ -370,7 +370,7 @@ private string Normalize(string text) .Replace("))on", ")on"); } - private async Task GetStoredProcedureText(string connStr, string storedProcedureName) + private async Task GetObjectText(string connStr, string storedProcedureName) { using var conn = new SqlConnection(connStr); await conn.OpenAsync(); diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs index 6ee15a5102..6ea158cc88 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs @@ -162,7 +162,7 @@ WHILE @i < 10000 public async Task RollTransactionForward() { ExecuteSql("TRUNCATE TABLE dbo.Transactions"); - ExecuteSql("TRUNCATE TABLE dbo.Resource"); + ExecuteSql("DELETE FROM dbo.Resource"); ExecuteSql("TRUNCATE TABLE dbo.NumberSearchParam"); using var cts = new CancellationTokenSource(); @@ -337,7 +337,7 @@ private long GetCount(string table) { using var conn = new SqlConnection(_fixture.TestConnectionString); conn.Open(); - using var cmd = new SqlCommand($"SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_id = object_id('{table}') AND index_id IN (0,1)", conn); + using var cmd = new SqlCommand($"SELECT count_big(*) FROM {table}", conn); var res = cmd.ExecuteScalar(); return (long)res; } diff --git a/tools/BlobRewriter/BlobRewriter.csproj b/tools/BlobRewriter/BlobRewriter.csproj index d166335c00..f8bf98667e 100644 --- a/tools/BlobRewriter/BlobRewriter.csproj +++ b/tools/BlobRewriter/BlobRewriter.csproj @@ -1,4 +1,4 @@ - + Exe diff --git a/tools/PerfTester/App.config b/tools/PerfTester/App.config index 78dff2f0d6..0a24f67e93 100644 --- a/tools/PerfTester/App.config +++ b/tools/PerfTester/App.config @@ -12,8 +12,10 @@ + + - + @@ -21,7 +23,7 @@ - + @@ -29,8 +31,10 @@ - - + + + + diff --git a/tools/PerfTester/Program.cs b/tools/PerfTester/Program.cs index 1c010f569c..a829927be9 100644 --- a/tools/PerfTester/Program.cs +++ b/tools/PerfTester/Program.cs @@ -13,6 +13,7 @@ using System.Security.Cryptography; using System.Text; using System.Threading; +using Azure.Identity; using Azure.Storage.Blobs; using Azure.Storage.Blobs.Specialized; using Microsoft.Data.SqlClient; @@ -29,6 +30,8 @@ public static class Program { private static readonly string _connectionString = ConfigurationManager.ConnectionStrings["Database"].ConnectionString; private static readonly string _storageConnectionString = ConfigurationManager.AppSettings["StorageConnectionString"]; + private static readonly string _storageUri = ConfigurationManager.AppSettings["StorageUri"]; + private static readonly string _storageUAMI = ConfigurationManager.AppSettings["StorageUAMI"]; private static readonly string _storageContainerName = ConfigurationManager.AppSettings["StorageContainerName"]; private static readonly string _storageBlobName = ConfigurationManager.AppSettings["StorageBlobName"]; private static readonly int _reportingPeriodSec = int.Parse(ConfigurationManager.AppSettings["ReportingPeriodSec"]); @@ -40,6 +43,8 @@ public static class Program private static readonly string _endpoint = ConfigurationManager.AppSettings["FhirEndpoint"]; private static readonly HttpClient _httpClient = new HttpClient(); private static readonly string _ndjsonStorageConnectionString = ConfigurationManager.AppSettings["NDJsonStorageConnectionString"]; + private static readonly string _ndjsonStorageUri = ConfigurationManager.AppSettings["NDJsonStorageUri"]; + private static readonly string _ndjsonStorageUAMI = ConfigurationManager.AppSettings["NDJsonStorageUAMI"]; private static readonly string _ndjsonStorageContainerName = ConfigurationManager.AppSettings["NDJsonStorageContainerName"]; private static readonly int _takeBlobs = int.Parse(ConfigurationManager.AppSettings["TakeBlobs"]); private static readonly int _skipBlobs = int.Parse(ConfigurationManager.AppSettings["SkipBlobs"]); @@ -181,56 +186,64 @@ private static void GetDate() private static void ExecuteParallelHttpPuts() { var resourceIds = _callType == "HttpUpdate" || _callType == "BundleUpdate" ? GetRandomIds() : new List<(short ResourceTypeId, string ResourceId)>(); - var sourceContainer = GetContainer(_ndjsonStorageConnectionString, _ndjsonStorageContainerName); + var sourceContainer = GetContainer(_ndjsonStorageConnectionString, _ndjsonStorageUri, _ndjsonStorageUAMI, _ndjsonStorageContainerName); var tableOrView = GetResourceObjectType(); - var sw = Stopwatch.StartNew(); - var swReport = Stopwatch.StartNew(); - var calls = 0L; - var resources = 0; - long sumLatency = 0; - var singleId = Guid.NewGuid().ToString(); - BatchExtensions.ExecuteInParallelBatches(GetLinesInBlobs(sourceContainer), _threads, 1, (thread, lineItem) => + for (var repeat = 0; repeat < _repeat; repeat++) { - if (Interlocked.Read(ref calls) >= _calls) + var sw = Stopwatch.StartNew(); + var swReport = Stopwatch.StartNew(); + var calls = 0L; + var errors = 0L; + var resources = 0; + long sumLatency = 0; + var singleId = Guid.NewGuid().ToString(); + BatchExtensions.ExecuteInParallelBatches(GetLinesInBlobs(sourceContainer), _threads, 1, (thread, lineItem) => { - return; - } + if (Interlocked.Read(ref calls) >= _calls) + { + return; + } - var callId = (int)Interlocked.Increment(ref calls) - 1; - if ((_callType == "HttpUpdate" || _callType == "BundleUpdate") && callId >= resourceIds.Count) - { - return; - } + var callId = (int)Interlocked.Increment(ref calls) - 1; + if ((_callType == "HttpUpdate" || _callType == "BundleUpdate") && callId >= resourceIds.Count) + { + return; + } - var resourceIdInput = _callType == "SingleId" - ? singleId - : _callType == "HttpUpdate" || _callType == "BundleUpdate" - ? resourceIds[callId].ResourceId - : Guid.NewGuid().ToString(); + var resourceIdInput = _callType == "SingleId" + ? singleId + : _callType == "HttpUpdate" || _callType == "BundleUpdate" + ? resourceIds[callId].ResourceId + : Guid.NewGuid().ToString(); - var swLatency = Stopwatch.StartNew(); - var json = lineItem.Item2.First(); - var (resourceType, resourceId) = ParseJson(ref json, resourceIdInput); - var status = _callType == "BundleUpdate" ? PostBundle(json, resourceType, resourceId) : PutResource(json, resourceType, resourceId); - Interlocked.Increment(ref resources); - var mcsec = (long)Math.Round(swLatency.Elapsed.TotalMilliseconds * 1000, 0); - Interlocked.Add(ref sumLatency, mcsec); - _store.TryLogEvent($"{tableOrView}.threads={_threads}.Put:{status}:{resourceType}/{resourceId}", "Warn", $"mcsec={mcsec}", null, CancellationToken.None).Wait(); + var swLatency = Stopwatch.StartNew(); + var json = lineItem.Item2.First(); + var (resourceType, resourceId) = ParseJson(ref json, resourceIdInput); + var status = _callType == "BundleUpdate" ? PostBundle(json, resourceType, resourceId) : PutResource(json, resourceType, resourceId); + Interlocked.Increment(ref resources); + var mcsec = (long)Math.Round(swLatency.Elapsed.TotalMilliseconds * 1000, 0); + Interlocked.Add(ref sumLatency, mcsec); + _store.TryLogEvent($"{tableOrView}.threads={_threads}.Put:{status}:{resourceType}/{resourceId}", "Warn", $"mcsec={mcsec}", null, CancellationToken.None).Wait(); + if (_callType != "BundleUpdate" && status != "OK" && status != "Created") + { + Interlocked.Increment(ref errors); + } - if (swReport.Elapsed.TotalSeconds > _reportingPeriodSec) - { - lock (swReport) + if (swReport.Elapsed.TotalSeconds > _reportingPeriodSec) { - if (swReport.Elapsed.TotalSeconds > _reportingPeriodSec) + lock (swReport) { - Console.WriteLine($"{tableOrView} type={_callType} writes={_writesEnabled} threads={_threads} calls={calls} resources={resources} latency={sumLatency / 1000.0 / calls} ms speed={(int)(calls / sw.Elapsed.TotalSeconds)} calls/sec elapsed={(int)sw.Elapsed.TotalSeconds} sec"); - swReport.Restart(); + if (swReport.Elapsed.TotalSeconds > _reportingPeriodSec) + { + Console.WriteLine($"{tableOrView} type={_callType} writes={_writesEnabled} threads={_threads} calls={calls} errors={errors} resources={resources} latency={sumLatency / 1000.0 / calls} ms speed={(int)(calls / sw.Elapsed.TotalSeconds)} calls/sec elapsed={(int)sw.Elapsed.TotalSeconds} sec"); + swReport.Restart(); + } } } - } - }); + }); - Console.WriteLine($"{tableOrView} type={_callType} writes={_writesEnabled} threads={_threads} calls={calls} resources={resources} latency={sumLatency / 1000.0 / calls} ms speed={(int)(calls / sw.Elapsed.TotalSeconds)} calls/sec elapsed={(int)sw.Elapsed.TotalSeconds} sec"); + Console.WriteLine($"{tableOrView} type={_callType} writes={_writesEnabled} threads={_threads} calls={calls} errors={errors} resources={resources} latency={sumLatency / 1000.0 / calls} ms speed={(int)(calls / sw.Elapsed.TotalSeconds)} calls/sec elapsed={(int)sw.Elapsed.TotalSeconds} sec"); + } } private static void ExecuteParallelCalls(ReadOnlyList tranIds) @@ -309,7 +322,7 @@ private static void ExecuteParallelCalls(ReadOnlyList<(short ResourceTypeId, str } else if (_callType.StartsWith("SearchByIds")) { - var status = GetResources(_nameFilter, resourceIds.Item2.Select(_ => _.ResourceId)?.ToList()); + var status = GetResources(_nameFilter, resourceIds.Item2.Select(_ => _.ResourceId)); if (status != "OK") { Interlocked.Increment(ref errors); @@ -341,7 +354,9 @@ private static void ExecuteParallelCalls(ReadOnlyList<(short ResourceTypeId, str throw new NotImplementedException(); } - Interlocked.Add(ref sumLatency, (long)Math.Round(swLatency.Elapsed.TotalMilliseconds * 1000, 0)); + var mcsec = (long)Math.Round(swLatency.Elapsed.TotalMilliseconds * 1000, 0); + Interlocked.Add(ref sumLatency, mcsec); + _store.TryLogEvent($"Threads={_threads}.{_callType}.{_nameFilter}", "Warn", $"mcsec={mcsec}", null, CancellationToken.None).Wait(); if (swReport.Elapsed.TotalSeconds > _reportingPeriodSec) { @@ -566,14 +581,14 @@ private static string GetResourceObjectType() private static BlobContainerClient GetContainer() { - return GetContainer(_storageConnectionString, _storageContainerName); + return GetContainer(_storageConnectionString, _storageUri, _storageUAMI, _storageContainerName); } - private static BlobContainerClient GetContainer(string storageConnectionString, string storageContainerName) + private static BlobContainerClient GetContainer(string storageConnectionString, string storageUri, string storageUAMI, string storageContainerName) { try { - var blobServiceClient = new BlobServiceClient(storageConnectionString); + var blobServiceClient = string.IsNullOrEmpty(storageUri) ? new BlobServiceClient(storageConnectionString) : new BlobServiceClient(new Uri(storageUri), string.IsNullOrEmpty(storageUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(storageUAMI)); var blobContainerClient = blobServiceClient.GetBlobContainerClient(storageContainerName); if (!blobContainerClient.Exists()) @@ -793,7 +808,7 @@ private static string PostBundle(string jsonString, string resourceType, string return status; } - private static string GetResources(string resourceType, System.Collections.Generic.IReadOnlyCollection resourceIds) + private static string GetResources(string resourceType, IEnumerable resourceIds) { var maxRetries = 3; var retries = 0; From 5d8d03a0c9959c14e72e8a30199d36f07c79745a Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 17 Oct 2024 19:14:08 -0700 Subject: [PATCH 004/111] Fix after merge --- .../HashingSqlQueryParameterManagerTests.cs | 4 +- .../Features/Schema/Migrations/84.sql | 774 ++++++++++++------ .../Schema/Sql/Sprocs/GetResourceVersions.sql | 8 +- .../Schema/Sql/Sprocs/GetResources.sql | 10 +- .../Schema/Sql/Sprocs/MergeResources.sql | 25 +- .../Sql/Tables/ReferenceSearchParam.sql | 25 +- .../Features/Schema/Sql/Tables/Resource.sql | 128 ++- .../Schema/Sql/Tables/ResourceIdIntMap.sql | 11 - .../Schema/Sql/Views/ReferenceSearchParam.sql | 48 +- .../Features/Schema/Sql/Views/Resource.sql | 67 +- .../Persistence/FhirStorageTests.cs | 8 +- 11 files changed, 671 insertions(+), 437 deletions(-) delete mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql diff --git a/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs b/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs index 65cf597f55..93cb18f0f2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs +++ b/src/Microsoft.Health.Fhir.SqlServer.UnitTests/Features/Search/HashingSqlQueryParameterManagerTests.cs @@ -34,8 +34,8 @@ public void GivenParametersThatShouldNotBeHashed_WhenAdded_ResultsInNoChangeToHa AssertDoesNotChangeHash(parameters, () => { parameters.AddParameter(1, includeInHash: false); - parameters.AddParameter(VLatest.ResourceCurrent.ResourceId, "abc", false); - parameters.AddParameter(VLatest.ResourceCurrent.ResourceId, (object)"123", false); + parameters.AddParameter(VLatest.Resource.ResourceId, "abc", false); + parameters.AddParameter(VLatest.Resource.ResourceId, (object)"123", false); }); Assert.False(parameters.HasParametersToHash); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 36d047ac78..bdfc970f31 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -61,6 +61,17 @@ CREATE SEQUENCE dbo.ResourceSurrogateIdUniquifierSequence CYCLE CACHE 1000000; + +GO +CREATE SEQUENCE dbo.ResourceIdIntMapSequence + AS INT + START WITH 0 + INCREMENT BY 1 + MINVALUE 0 + MAXVALUE 79999 + CYCLE + CACHE 1000000; + CREATE TYPE dbo.BigintList AS TABLE ( Id BIGINT NOT NULL PRIMARY KEY); @@ -132,10 +143,11 @@ CREATE TYPE dbo.ResourceList AS TABLE ( IsDeleted BIT NOT NULL, IsHistory BIT NOT NULL, KeepHistory BIT NOT NULL, - RawResource VARBINARY (MAX) NOT NULL, + RawResource VARBINARY (MAX) NULL, IsRawResourceMetaSet BIT NOT NULL, RequestMethod VARCHAR (10) NULL, - SearchParamHash VARCHAR (64) NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), + SearchParamHash VARCHAR (64) NULL, + OffsetInFile INT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), UNIQUE (ResourceTypeId, ResourceId, Version)); CREATE TYPE dbo.ResourceWriteClaimList AS TABLE ( @@ -532,19 +544,40 @@ CREATE TABLE dbo.ReferenceSearchParam ( ResourceSurrogateId BIGINT NOT NULL, SearchParamId SMALLINT NOT NULL, BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, - ReferenceResourceTypeId SMALLINT NULL, - ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceTypeId SMALLINT NOT NULL, + ReferenceResourceIdInt BIGINT CONSTRAINT DF_ReferenceSearchParam_ResourceIdInt DEFAULT 0 NOT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS CONSTRAINT DF_ReferenceSearchParam_ResourceId DEFAULT '' NOT NULL, + ReferenceResourceVersion INT NULL, + CONSTRAINT CH_ReferenceSearchParam_ReferenceResourceIdInt_ReferenceResourceId CHECK (ReferenceResourceIdInt = 0 + AND ReferenceResourceId <> '' + OR ReferenceResourceIdInt <> 0 + AND ReferenceResourceId = '') +); + + +GO +DROP TABLE dbo.ReferenceSearchParam; + + +GO +CREATE TABLE dbo.ReferenceSearchParams ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NOT NULL, + ReferenceResourceIdInt BIGINT NOT NULL, ReferenceResourceVersion INT NULL ); -ALTER TABLE dbo.ReferenceSearchParam SET (LOCK_ESCALATION = AUTO); +ALTER TABLE dbo.ReferenceSearchParams SET (LOCK_ESCALATION = AUTO); -CREATE CLUSTERED INDEX IXC_ReferenceSearchParam - ON dbo.ReferenceSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) +CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.ReferenceSearchParams(ResourceSurrogateId, SearchParamId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId); -CREATE UNIQUE INDEX IXU_ReferenceResourceId_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId - ON dbo.ReferenceSearchParam(ReferenceResourceId, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) +CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.ReferenceSearchParams(ReferenceResourceIdInt, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId); CREATE TABLE dbo.ReferenceTokenCompositeSearchParam ( @@ -584,6 +617,17 @@ CREATE TABLE dbo.ReindexJob ( CONSTRAINT PKC_ReindexJob PRIMARY KEY CLUSTERED (Id) ); +CREATE TABLE dbo.ResourceIdIntMap ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.ResourceIdIntMap SET (LOCK_ESCALATION = AUTO); + + +GO CREATE TABLE dbo.RawResources ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL, @@ -594,119 +638,89 @@ ALTER TABLE dbo.RawResources SET (LOCK_ESCALATION = AUTO); GO -CREATE TABLE dbo.ResourceCurrent ( +CREATE TABLE dbo.Resource ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL, ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, Version INT NOT NULL, - IsHistory BIT CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0 NOT NULL, + IsHistory BIT NOT NULL, IsDeleted BIT NOT NULL, RequestMethod VARCHAR (10) NULL, RawResource VARBINARY (MAX) NULL, - IsRawResourceMetaSet BIT CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + IsRawResourceMetaSet BIT NOT NULL, SearchParamHash VARCHAR (64) NULL, TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), - CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceId UNIQUE (ResourceTypeId, ResourceId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + HistoryTransactionId BIGINT NULL, + OffsetInFile INT NULL ); -ALTER TABLE dbo.ResourceCurrent SET (LOCK_ESCALATION = AUTO); - -CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL - ON dbo.ResourceCurrent(ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - -CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL - ON dbo.ResourceCurrent(ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - GO -EXECUTE sp_rename 'ResourceCurrent', 'ResourceCurrentTbl'; +DROP TABLE dbo.Resource; GO -CREATE VIEW dbo.ResourceCurrent -AS -SELECT A.ResourceTypeId, - A.ResourceSurrogateId, - ResourceId, - Version, - IsHistory, - IsDeleted, - RequestMethod, - B.RawResource, - IsRawResourceMetaSet, - SearchParamHash, - TransactionId, - HistoryTransactionId -FROM dbo.ResourceCurrentTbl AS A - LEFT OUTER JOIN - dbo.RawResources AS B - ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId; - - -GO -CREATE TABLE dbo.ResourceHistory ( +CREATE TABLE dbo.CurrentResources ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL, - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ResourceIdInt BIGINT NOT NULL, Version INT NOT NULL, - IsHistory BIT CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1 NOT NULL, + IsHistory BIT CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0 NOT NULL, IsDeleted BIT NOT NULL, RequestMethod VARCHAR (10) NULL, RawResource VARBINARY (MAX) NULL, - IsRawResourceMetaSet BIT CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, SearchParamHash VARCHAR (64) NULL, TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1), - CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + HistoryTransactionId BIGINT NULL, + OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), + CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_CurrentResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL + OR OffsetInFile IS NOT NULL) ); -ALTER TABLE dbo.ResourceHistory SET (LOCK_ESCALATION = AUTO); +ALTER TABLE dbo.CurrentResources SET (LOCK_ESCALATION = AUTO); -CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL - ON dbo.ResourceHistory(ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL + ON dbo.CurrentResources(TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId); -CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL - ON dbo.ResourceHistory(ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL + ON dbo.CurrentResources(HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId); GO -EXECUTE sp_rename 'ResourceHistory', 'ResourceHistoryTbl'; - +CREATE TABLE dbo.HistoryResources ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + IsHistory BIT CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1 NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1), + CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_HistoryResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL + OR OffsetInFile IS NOT NULL) +); -GO -CREATE VIEW dbo.ResourceHistory -AS -SELECT A.ResourceTypeId, - A.ResourceSurrogateId, - ResourceId, - Version, - IsHistory, - IsDeleted, - RequestMethod, - B.RawResource, - IsRawResourceMetaSet, - SearchParamHash, - TransactionId, - HistoryTransactionId -FROM dbo.ResourceHistoryTbl AS A - LEFT OUTER JOIN - dbo.RawResources AS B - ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId; +ALTER TABLE dbo.HistoryResources SET (LOCK_ESCALATION = AUTO); +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL + ON dbo.HistoryResources(TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); -GO -CREATE TABLE dbo.Dummy ( - Dummy INT -); +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL + ON dbo.HistoryResources(HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); CREATE TABLE dbo.ResourceChangeData ( Id BIGINT IDENTITY (1, 1) NOT NULL, @@ -1430,6 +1444,32 @@ BEGIN CATCH THROW; END CATCH +GO +CREATE PROCEDURE dbo.AssignResourceIdInts +@Count INT, @FirstIdInt BIGINT OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'AssignResourceIdInts', @Mode AS VARCHAR (200) = 'Cnt=' + CONVERT (VARCHAR, @Count), @st AS DATETIME = getUTCdate(), @FirstValueVar AS SQL_VARIANT, @LastValueVar AS SQL_VARIANT, @SequenceRangeFirstValue AS INT; +BEGIN TRY + SET @FirstValueVar = NULL; + WHILE @FirstValueVar IS NULL + BEGIN + EXECUTE sys.sp_sequence_get_range @sequence_name = 'dbo.ResourceIdIntMapSequence', @range_size = @Count, @range_first_value = @FirstValueVar OUTPUT, @range_last_value = @LastValueVar OUTPUT; + SET @SequenceRangeFirstValue = CONVERT (INT, @FirstValueVar); + IF @SequenceRangeFirstValue > CONVERT (INT, @LastValueVar) + SET @FirstValueVar = NULL; + END + SET @FirstIdInt = datediff_big(millisecond, '0001-01-01', sysUTCdatetime()) * 80000 + @SequenceRangeFirstValue; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + GO CREATE PROCEDURE dbo.CaptureResourceChanges @isDeleted BIT, @version INT, @resourceId VARCHAR (64), @resourceTypeId SMALLINT @@ -2786,7 +2826,7 @@ CREATE PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY AS SET NOCOUNT ON; -DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResources', @InputRows AS INT, @DummyTop AS BIGINT = 9223372036854775807, @NotNullVersionExists AS BIT, @NullVersionExists AS BIT, @MinRT AS SMALLINT, @MaxRT AS SMALLINT; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResources', @InputRows AS INT, @NotNullVersionExists AS BIT, @NullVersionExists AS BIT, @MinRT AS SMALLINT, @MaxRT AS SMALLINT; SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @@ -2800,76 +2840,98 @@ BEGIN TRY SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - B.Version, + C.Version, IsDeleted, IsHistory, RawResource, IsRawResourceMetaSet, - SearchParamHash - FROM (SELECT TOP (@DummyTop) * + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT * FROM @ResourceKeys) AS A - INNER JOIN - dbo.Resource AS B + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - AND B.Version = A.Version - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + INNER LOOP JOIN + dbo.Resource AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.Version = A.Version + OPTION (MAXDOP 1); ELSE SELECT * FROM (SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - B.Version, + C.Version, IsDeleted, IsHistory, RawResource, IsRawResourceMetaSet, - SearchParamHash - FROM (SELECT TOP (@DummyTop) * + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) AS A - INNER JOIN - dbo.Resource AS B + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - AND B.Version = A.Version + INNER LOOP JOIN + dbo.Resource AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.Version = A.Version UNION ALL SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - B.Version, + C.Version, IsDeleted, IsHistory, RawResource, IsRawResourceMetaSet, - SearchParamHash - FROM (SELECT TOP (@DummyTop) * + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) AS A - INNER JOIN - dbo.Resource AS B + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - WHERE IsHistory = 0) AS A - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + INNER LOOP JOIN + dbo.CurrentResources AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt) AS A + OPTION (MAXDOP 1); ELSE SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - B.Version, + C.Version, IsDeleted, IsHistory, RawResource, IsRawResourceMetaSet, - SearchParamHash - FROM (SELECT TOP (@DummyTop) * + SearchParamHash, + TransactionId, + OffsetInFile + FROM (SELECT * FROM @ResourceKeys) AS A - INNER JOIN - dbo.Resource AS B + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - WHERE IsHistory = 0 - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + INNER LOOP JOIN + dbo.CurrentResources AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + OPTION (MAXDOP 1); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; END TRY BEGIN CATCH @@ -2919,7 +2981,9 @@ BEGIN TRY RawResource, IsRawResourceMetaSet, SearchParamHash, - RequestMethod + RequestMethod, + TransactionId, + OffsetInFile FROM (SELECT TOP (@DummyTop) * FROM @Keys) AS A INNER JOIN @@ -3001,7 +3065,9 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource + RawResource, + TransactionId, + OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId @@ -3020,7 +3086,9 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource + RawResource, + TransactionId, + OffsetInFile FROM @SurrogateIds INNER JOIN dbo.Resource @@ -3131,31 +3199,38 @@ BEGIN TRY A.ResourceSurrogateId, CASE WHEN D.Version IS NOT NULL THEN 0 WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex ELSE isnull(M.Version, 0) - ResourceIndex END AS Version, isnull(D.Version, 0) AS MatchedVersion, - D.RawResource AS MatchedRawResource - FROM (SELECT TOP (@DummyTop) *, - CONVERT (INT, row_number() OVER (PARTITION BY ResourceTypeId, ResourceId ORDER BY ResourceSurrogateId DESC)) AS ResourceIndex - FROM @ResourceDateKeys) AS A OUTER APPLY (SELECT TOP 1 * - FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) - WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = A.ResourceId - AND B.Version > 0 - AND B.ResourceSurrogateId < A.ResourceSurrogateId - ORDER BY B.ResourceSurrogateId DESC) AS L OUTER APPLY (SELECT TOP 1 * - FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) - WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = A.ResourceId - AND B.Version > 0 - AND B.ResourceSurrogateId > A.ResourceSurrogateId - ORDER BY B.ResourceSurrogateId) AS U OUTER APPLY (SELECT TOP 1 * - FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) - WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = A.ResourceId - AND B.Version < 0 - ORDER BY B.Version) AS M OUTER APPLY (SELECT TOP 1 * - FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) - WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = A.ResourceId - AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) AS D + D.RawResource AS MatchedRawResource, + D.TransactionId AS MatchedTransactionId, + D.OffsetInFile AS MatchedOffsetInFile + FROM (SELECT TOP (@DummyTop) A.*, + M.ResourceIdInt, + CONVERT (INT, row_number() OVER (PARTITION BY A.ResourceTypeId, A.ResourceId ORDER BY ResourceSurrogateId DESC)) AS ResourceIndex + FROM @ResourceDateKeys AS A + LEFT OUTER JOIN + dbo.ResourceIdIntMap AS M WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + ON M.ResourceTypeId = A.ResourceTypeId + AND M.ResourceId = A.ResourceId) AS A OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt + AND B.Version > 0 + AND B.ResourceSurrogateId < A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId DESC) AS L OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt + AND B.Version > 0 + AND B.ResourceSurrogateId > A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId) AS U OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt + AND B.Version < 0 + ORDER BY B.Version) AS M OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt + AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) AS D OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; END TRY @@ -3261,13 +3336,10 @@ BEGIN TRY dbo.ResourceWriteClaim AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); - DELETE B - FROM @SurrogateIds AS A - INNER LOOP JOIN - dbo.ReferenceSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) - ON B.ResourceTypeId = @ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId - OPTION (MAXDOP 1); + DELETE dbo.ReferenceSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); DELETE B FROM @SurrogateIds AS A INNER LOOP JOIN @@ -3455,11 +3527,218 @@ CREATE PROCEDURE dbo.MergeResources @AffectedRows INT=0 OUTPUT, @RaiseExceptionOnConflict BIT=1, @IsResourceChangeCaptureEnabled BIT=0, @TransactionId BIGINT=NULL, @SingleTransaction BIT=1, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParms dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS SET NOCOUNT ON; -DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0, @RT AS SMALLINT, @NewIdsCount AS INT, @FirstIdInt AS BIGINT; DECLARE @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) FROM @Resources), 'Input=Empty'); SET @Mode += ' E=' + CONVERT (VARCHAR, @RaiseExceptionOnConflict) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled) + ' IT=' + CONVERT (VARCHAR, @InitialTranCount) + ' T=' + isnull(CONVERT (VARCHAR, @TransactionId), 'NULL'); SET @AffectedRows = 0; +RetryResourceIdIntMapInsert: +BEGIN TRY + DECLARE @RTs AS TABLE ( + ResourceTypeId SMALLINT NOT NULL PRIMARY KEY); + DECLARE @InputIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @ExistingIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @InsertIds AS TABLE ( + ResourceIndex INT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL); + DECLARE @InsertedIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @ResourcesWithIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + HasVersionToCompare BIT NOT NULL, + IsDeleted BIT NOT NULL, + IsHistory BIT NOT NULL, + KeepHistory BIT NOT NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + SearchParamHash VARCHAR (64) NULL, + OffsetInFile INT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), + UNIQUE (ResourceTypeId, ResourceIdInt, Version)); + DECLARE @ReferenceSearchParamsWithIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceIdInt BIGINT NOT NULL, + ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt)); + INSERT INTO @InputIds + SELECT DISTINCT ReferenceResourceTypeId, + ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NOT NULL; + INSERT INTO @RTs + SELECT DISTINCT ResourceTypeId + FROM @InputIds; + WHILE EXISTS (SELECT * + FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId + FROM @RTs); + INSERT INTO @ExistingIds (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT @RT, + ResourceIdInt, + A.ResourceId + FROM (SELECT * + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId; + DELETE @InsertIds; + INSERT INTO @InsertIds (ResourceIndex, ResourceId) + SELECT row_number() OVER (ORDER BY ResourceId) - 1 AS RowId, + ResourceId + FROM (SELECT ResourceId + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + WHERE NOT EXISTS (SELECT * + FROM @ExistingIds AS B + WHERE B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId); + SET @NewIdsCount = (SELECT count(*) + FROM @InsertIds); + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; + INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, + ResourceIndex + @FirstIdInt, + ResourceId + FROM @InsertIds; + END + DELETE @RTs + WHERE ResourceTypeId = @RT; + END + INSERT INTO @ReferenceSearchParamsWithIds (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT A.ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + isnull(C.ResourceIdInt, B.ResourceIdInt), + ReferenceResourceVersion + FROM @ReferenceSearchParams AS A + LEFT OUTER JOIN + @InsertedIds AS B + ON B.ResourceTypeId = A.ReferenceResourceTypeId + AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN + @ExistingIds AS C + ON C.ResourceTypeId = A.ReferenceResourceTypeId + AND C.ResourceId = A.ReferenceResourceId; + DELETE @InputIds; + DELETE @RTs; + DELETE @InsertedIds; + DELETE @ExistingIds; + INSERT INTO @InputIds + SELECT ResourceTypeId, + ResourceId + FROM @Resources + GROUP BY ResourceTypeId, ResourceId; + INSERT INTO @RTs + SELECT DISTINCT ResourceTypeId + FROM @InputIds; + WHILE EXISTS (SELECT * + FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId + FROM @RTs); + INSERT INTO @ExistingIds (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT @RT, + ResourceIdInt, + A.ResourceId + FROM (SELECT * + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId; + DELETE @InsertIds; + INSERT INTO @InsertIds (ResourceIndex, ResourceId) + SELECT row_number() OVER (ORDER BY ResourceId) - 1 AS RowId, + ResourceId + FROM (SELECT ResourceId + FROM @InputIds + WHERE ResourceTypeId = @RT) AS A + WHERE NOT EXISTS (SELECT * + FROM @ExistingIds AS B + WHERE B.ResourceTypeId = @RT + AND B.ResourceId = A.ResourceId); + SET @NewIdsCount = (SELECT count(*) + FROM @InsertIds); + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; + INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, + ResourceIndex + @FirstIdInt, + ResourceId + FROM @InsertIds; + END + DELETE @RTs + WHERE ResourceTypeId = @RT; + END + INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile) + SELECT A.ResourceTypeId, + isnull(C.ResourceIdInt, B.ResourceIdInt), + Version, + HasVersionToCompare, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + KeepHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + OffsetInFile + FROM @Resources AS A + LEFT OUTER JOIN + @InsertedIds AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN + @ExistingIds AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceId = A.ResourceId; +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 + AND @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + IF error_number() IN (2601, 2627) + AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' + BEGIN + DELETE @ResourcesWithIds; + DELETE @ReferenceSearchParamsWithIds; + DELETE @InputIds; + DELETE @RTs; + DELETE @InsertedIds; + DELETE @ExistingIds; + GOTO RetryResourceIdIntMapInsert; + END + ELSE + THROW; +END CATCH BEGIN TRY DECLARE @Existing AS TABLE ( ResourceTypeId SMALLINT NOT NULL, @@ -3525,12 +3804,12 @@ BEGIN TRY B.Version, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * - FROM @Resources + FROM @ResourcesWithIds WHERE HasVersionToCompare = 1) AS A LEFT OUTER JOIN - dbo.Resource AS B + dbo.CurrentResources AS B ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = A.ResourceId + AND B.ResourceIdInt = A.ResourceIdInt AND B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); IF @RaiseExceptionOnConflict = 1 @@ -3583,7 +3862,7 @@ BEGIN TRY FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; - DELETE dbo.ReferenceSearchParam + DELETE dbo.ReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId @@ -3668,9 +3947,9 @@ BEGIN TRY AND SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; END - INSERT INTO dbo.Resource (ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId) + INSERT INTO dbo.CurrentResources (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile) SELECT ResourceTypeId, - ResourceId, + ResourceIdInt, Version, IsHistory, ResourceSurrogateId, @@ -3679,8 +3958,26 @@ BEGIN TRY RawResource, IsRawResourceMetaSet, SearchParamHash, - @TransactionId - FROM @Resources; + @TransactionId, + OffsetInFile + FROM @ResourcesWithIds + WHERE IsHistory = 0; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile) + SELECT ResourceTypeId, + ResourceIdInt, + Version, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + @TransactionId, + OffsetInFile + FROM @ResourcesWithIds + WHERE IsHistory = 1; SET @AffectedRows += @@rowcount; INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) SELECT ResourceSurrogateId, @@ -3688,15 +3985,15 @@ BEGIN TRY ClaimValue FROM @ResourceWriteClaims; SET @AffectedRows += @@rowcount; - INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + INSERT INTO dbo.ReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - ReferenceResourceId, + ReferenceResourceIdInt, ReferenceResourceVersion - FROM @ReferenceSearchParams; + FROM @ReferenceSearchParamsWithIds; SET @AffectedRows += @@rowcount; INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) SELECT ResourceTypeId, @@ -3857,22 +4154,22 @@ BEGIN TRY WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); SET @AffectedRows += @@rowcount; - INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) - SELECT ResourceTypeId, + INSERT INTO dbo.ReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - ReferenceResourceId, + ReferenceResourceIdInt, ReferenceResourceVersion FROM (SELECT TOP (@DummyTop) * - FROM @ReferenceSearchParams) AS A + FROM @ReferenceSearchParamsWithIds) AS A WHERE EXISTS (SELECT * FROM @Existing AS B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * - FROM dbo.ReferenceSearchParam AS C + FROM dbo.ReferenceSearchParams AS C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); @@ -4169,6 +4466,8 @@ BEGIN CATCH IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' + OR error_message() LIKE '%''dbo.CurrentResources%' + OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; ELSE @@ -4943,17 +5242,18 @@ BEGIN TRY ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL); BEGIN TRANSACTION; - UPDATE A + UPDATE B SET SearchParamHash = (SELECT SearchParamHash - FROM @Resources AS B - WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId) - FROM dbo.Resource AS A - WHERE IsHistory = 0 - AND EXISTS (SELECT * - FROM @Resources AS B - WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId); + FROM @Resources AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource AS B + WHERE EXISTS (SELECT * + FROM @Resources AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0; SET @Rows = @@rowcount; DELETE B FROM @Ids AS A @@ -4961,11 +5261,11 @@ BEGIN TRY dbo.ResourceWriteClaim AS B ON B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B - FROM @Ids AS A - INNER JOIN - dbo.ReferenceSearchParam AS B - ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId; + FROM dbo.ReferenceSearchParam AS B + WHERE EXISTS (SELECT * + FROM @Ids AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId); DELETE B FROM @Ids AS A INNER JOIN @@ -5230,74 +5530,71 @@ WHERE upsertedSearchParam.Action = 'INSERT'; COMMIT TRANSACTION; GO -CREATE VIEW dbo.Resource +CREATE VIEW dbo.ReferenceSearchParam AS -SELECT ResourceTypeId, +SELECT A.ResourceTypeId, ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + B.ResourceId AS ReferenceResourceId, + ReferenceResourceVersion +FROM dbo.ReferenceSearchParams AS A + LEFT OUTER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ReferenceResourceTypeId + AND B.ResourceIdInt = A.ReferenceResourceIdInt; + +GO +CREATE VIEW dbo.Resource +AS +SELECT A.ResourceTypeId, + A.ResourceSurrogateId, ResourceId, + A.ResourceIdInt, Version, IsHistory, IsDeleted, RequestMethod, - RawResource, + B.RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, - HistoryTransactionId -FROM dbo.ResourceHistory + HistoryTransactionId, + OffsetInFile +FROM dbo.CurrentResources AS A + LEFT OUTER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN + dbo.ResourceIdIntMap AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = A.ResourceIdInt UNION ALL -SELECT ResourceTypeId, - ResourceSurrogateId, +SELECT A.ResourceTypeId, + A.ResourceSurrogateId, ResourceId, + A.ResourceIdInt, Version, IsHistory, IsDeleted, RequestMethod, - RawResource, + B.RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, - HistoryTransactionId -FROM dbo.ResourceCurrent; - - -GO -CREATE TRIGGER dbo.ResourceIns - ON dbo.Resource - INSTEAD OF INSERT - AS BEGIN - INSERT INTO dbo.RawResources (ResourceTypeId, ResourceSurrogateId, RawResource) - SELECT ResourceTypeId, - ResourceSurrogateId, - RawResource - FROM Inserted; - INSERT INTO dbo.ResourceCurrentTbl (ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId) - SELECT ResourceTypeId, - ResourceSurrogateId, - ResourceId, - Version, - IsDeleted, - RequestMethod, - IsRawResourceMetaSet, - SearchParamHash, - TransactionId, - HistoryTransactionId - FROM Inserted - WHERE IsHistory = 0; - INSERT INTO dbo.ResourceHistoryTbl (ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId) - SELECT ResourceTypeId, - ResourceSurrogateId, - ResourceId, - Version, - IsDeleted, - RequestMethod, - IsRawResourceMetaSet, - SearchParamHash, - TransactionId, - HistoryTransactionId - FROM Inserted - WHERE IsHistory = 1; - END + HistoryTransactionId, + OffsetInFile +FROM dbo.HistoryResources AS A + LEFT OUTER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN + dbo.ResourceIdIntMap AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = A.ResourceIdInt; GO @@ -5324,7 +5621,7 @@ CREATE TRIGGER dbo.ResourceUpd HistoryTransactionId = A.HistoryTransactionId FROM Inserted AS A INNER JOIN - dbo.ResourceCurrentTbl AS B + dbo.CurrentResources AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; RETURN; @@ -5336,7 +5633,7 @@ CREATE TRIGGER dbo.ResourceUpd SET SearchParamHash = A.SearchParamHash FROM Inserted AS A INNER JOIN - dbo.ResourceCurrentTbl AS B + dbo.CurrentResources AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE A.IsHistory = 0; @@ -5353,23 +5650,24 @@ CREATE TRIGGER dbo.ResourceUpd IF NOT UPDATE (IsHistory) RAISERROR ('Generic updates are not supported via Resource view', 18, 127); DELETE A - FROM dbo.ResourceCurrentTbl AS A + FROM dbo.CurrentResources AS A WHERE EXISTS (SELECT * FROM Inserted AS B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1); - INSERT INTO dbo.ResourceHistoryTbl (ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId) + INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile) SELECT ResourceTypeId, ResourceSurrogateId, - ResourceId, + ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, - HistoryTransactionId + HistoryTransactionId, + OffsetInFile FROM Inserted WHERE IsHistory = 1; END @@ -5381,14 +5679,14 @@ CREATE TRIGGER dbo.ResourceDel INSTEAD OF DELETE AS BEGIN DELETE A - FROM dbo.ResourceCurrentTbl AS A + FROM dbo.CurrentResources AS A WHERE EXISTS (SELECT * FROM Deleted AS B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0); DELETE A - FROM dbo.ResourceHistoryTbl AS A + FROM dbo.HistoryResources AS A WHERE EXISTS (SELECT * FROM Deleted AS B WHERE B.ResourceTypeId = A.ResourceTypeId diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql index d93e343ae2..6e3219ad68 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql @@ -29,10 +29,10 @@ BEGIN TRY FROM @ResourceDateKeys A LEFT OUTER JOIN dbo.ResourceIdIntMap M WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON M.ResourceTypeId = A.ResourceTypeId AND M.ResourceId = A.ResourceId ) A - OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower - OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper - OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version < 0 ORDER BY B.Version) M -- minus - OUTER APPLY (SELECT TOP 1 * FROM dbo.ResourceTbl B WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version < 0 ORDER BY B.Version) M -- minus + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index 1d5b5a77fb..af534fc223 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -31,7 +31,7 @@ BEGIN TRY ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version OPTION (MAXDOP 1) ELSE SELECT * @@ -48,7 +48,7 @@ BEGIN TRY ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_Version_ResourceTypeId) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' AND C.Version = A.Version + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId @@ -63,8 +63,7 @@ BEGIN TRY ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' - WHERE IsHistory = 0 + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt ) A OPTION (MAXDOP 1) ELSE @@ -81,8 +80,7 @@ BEGIN TRY ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.ResourceTbl C WITH (INDEX = IXU_ResourceIdInt_ResourceId_ResourceTypeId_INCLUDE_Version_IsDeleted_WHERE_IsHistory_0) ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.ResourceId = '' - WHERE IsHistory = 0 + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 4f4ccf5fd9..4b717476b7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -42,6 +42,7 @@ SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(var SET @AffectedRows = 0 +RetryResourceIdIntMapInsert: BEGIN TRY DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) @@ -228,7 +229,7 @@ BEGIN TRY BEGIN IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - --WHERE B.IsHistory = 0 -- With this clause wrong plans are created on empty/small database. Commented until resource separation is in place. + WHERE B.IsHistory = 0 ) BEGIN BEGIN TRANSACTION @@ -259,7 +260,7 @@ BEGIN TRY ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds WHERE HasVersionToCompare = 1) A - LEFT OUTER JOIN dbo.ResourceTbl B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. + LEFT OUTER JOIN dbo.CurrentResources B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) @@ -291,7 +292,7 @@ BEGIN TRY DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount - DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + DELETE FROM dbo.ReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount @@ -323,10 +324,18 @@ BEGIN TRY --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' END - INSERT INTO dbo.ResourceTbl + INSERT INTO dbo.CurrentResources ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile ) SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, OffsetInFile FROM @ResourcesWithIds + WHERE IsHistory = 0 + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile ) + SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, OffsetInFile + FROM @ResourcesWithIds + WHERE IsHistory = 1 SET @AffectedRows += @@rowcount INSERT INTO dbo.ResourceWriteClaim @@ -335,7 +344,7 @@ BEGIN TRY FROM @ResourceWriteClaims SET @AffectedRows += @@rowcount - INSERT INTO dbo.ReferenceSearchParamTbl + INSERT INTO dbo.ReferenceSearchParams ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion FROM @ReferenceSearchParamsWithIds @@ -430,12 +439,12 @@ BEGIN TRY OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount - INSERT INTO dbo.ReferenceSearchParamTbl + INSERT INTO dbo.ReferenceSearchParams ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParamsWithIds) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) - AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParamTbl C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount @@ -573,7 +582,7 @@ BEGIN CATCH EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.RawResources''%') -- handles old and separated tables + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') -- handles old and separated tables THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; ELSE THROW diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index 45e794f558..2c3d9b0e1d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -11,17 +11,28 @@ ,CONSTRAINT CH_ReferenceSearchParam_ReferenceResourceIdInt_ReferenceResourceId CHECK (ReferenceResourceIdInt = 0 AND ReferenceResourceId <> '' OR ReferenceResourceIdInt <> 0 AND ReferenceResourceId = '') ) +GO +DROP TABLE dbo.ReferenceSearchParam +GO +CREATE TABLE dbo.ReferenceSearchParams +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,ReferenceResourceVersion int NULL +) -ALTER TABLE dbo.ReferenceSearchParam SET ( LOCK_ESCALATION = AUTO ) +ALTER TABLE dbo.ReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) -CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId - ON dbo.ReferenceSearchParam (ResourceSurrogateId, SearchParamId, ResourceTypeId) +CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId ON dbo.ReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceId_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId ON dbo.ReferenceSearchParam +CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId ON dbo.ReferenceSearchParams ( ReferenceResourceIdInt - ,ReferenceResourceId ,ReferenceResourceTypeId ,SearchParamId ,BaseUri @@ -29,6 +40,4 @@ CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceId_ReferenceReso ,ResourceTypeId ) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - - - +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql index 6485dc0944..1ccc3caff9 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql @@ -1,4 +1,16 @@ -CREATE TABLE dbo.RawResources +CREATE TABLE dbo.ResourceIdIntMap +( + ResourceTypeId smallint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + + CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +) + +ALTER TABLE dbo.ResourceIdIntMap SET ( LOCK_ESCALATION = AUTO ) +GO +CREATE TABLE dbo.RawResources ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL @@ -9,100 +21,74 @@ ALTER TABLE dbo.RawResources SET ( LOCK_ESCALATION = AUTO ) GO -CREATE TABLE dbo.ResourceCurrent +CREATE TABLE dbo.Resource ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL - ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT DF_Resource_ResourceId DEFAULT '' - ,ResourceIdInt bigint NOT NULL CONSTRAINT DF_Resource_ResourceIdInt DEFAULT 0 + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ,Version int NOT NULL - ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) + ,IsHistory bit NOT NULL ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,RawResource varbinary(max) NULL - ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 + ,IsRawResourceMetaSet bit NOT NULL ,SearchParamHash varchar(64) NULL - ,TransactionId bigint NULL -- used for main CRUD operation - ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL ,OffsetInFile int NULL - CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - ,CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceIdInt UNIQUE (ResourceTypeId, ResourceId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - ,CONSTRAINT CH_ResourceCurrent_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) - ,CONSTRAINT CH_ResourceCurrent_ResourceIdInt_ResourceId CHECK (ResourceIdInt = 0 AND ResourceId <> '' OR ResourceIdInt <> 0 AND ResourceId = '') ) - -ALTER TABLE dbo.ResourceCurrent SET ( LOCK_ESCALATION = AUTO ) - -CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) GO -EXECUTE sp_rename 'ResourceCurrent', 'ResourceCurrentTbl' +DROP TABLE dbo.Resource GO -CREATE VIEW dbo.ResourceCurrent -AS -SELECT A.ResourceTypeId - ,A.ResourceSurrogateId - ,ResourceId - ,Version - ,IsHistory - ,IsDeleted - ,RequestMethod - ,B.RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,TransactionId - ,HistoryTransactionId - ,OffsetInFile - FROM dbo.ResourceCurrentTbl A - LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -GO -CREATE TABLE dbo.ResourceHistory +CREATE TABLE dbo.CurrentResources ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL - ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT DF_Resource_ResourceId DEFAULT '' - ,ResourceIdInt bigint NOT NULL CONSTRAINT DF_Resource_ResourceIdInt DEFAULT 0 + ,ResourceIdInt bigint NOT NULL ,Version int NOT NULL - ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1, CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1) + ,IsHistory bit NOT NULL CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,RawResource varbinary(max) NULL - ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 + ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 ,SearchParamHash varchar(64) NULL - ,TransactionId bigint NULL -- used for main CRUD operation - ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL ,OffsetInFile int NULL - CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - ,CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - ,CONSTRAINT CH_ResourceHistory_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) - ,CONSTRAINT CH_ResourceHistory_ResourceIdInt_ResourceId CHECK (ResourceIdInt = 0 AND ResourceId <> '' OR ResourceIdInt <> 0 AND ResourceId = '') + CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT CH_CurrentResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) ) -ALTER TABLE dbo.ResourceHistory SET ( LOCK_ESCALATION = AUTO ) +ALTER TABLE dbo.CurrentResources SET ( LOCK_ESCALATION = AUTO ) -CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -GO -EXECUTE sp_rename 'ResourceHistory', 'ResourceHistoryTbl' -GO -CREATE VIEW dbo.ResourceHistory -AS -SELECT A.ResourceTypeId - ,A.ResourceSurrogateId - ,ResourceId - ,Version - ,IsHistory - ,IsDeleted - ,RequestMethod - ,B.RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,TransactionId - ,HistoryTransactionId - ,OffsetInFile - FROM dbo.ResourceHistoryTbl A - LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.CurrentResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.CurrentResources (HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) GO -CREATE TABLE dbo.Dummy (Dummy int) +CREATE TABLE dbo.HistoryResources +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,IsHistory bit NOT NULL CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1, CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1) + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL + ,OffsetInFile int NULL + + CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT CH_HistoryResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) +) + +ALTER TABLE dbo.HistoryResources SET ( LOCK_ESCALATION = AUTO ) + +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.HistoryResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.HistoryResources (HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql deleted file mode 100644 index 9ca9dfe62e..0000000000 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ResourceIdIntMap.sql +++ /dev/null @@ -1,11 +0,0 @@ -CREATE TABLE dbo.ResourceIdIntMap -( - ResourceTypeId smallint NOT NULL - ,ResourceIdInt bigint NOT NULL - ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL - - CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - ,CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -) - -ALTER TABLE dbo.ResourceIdIntMap SET ( LOCK_ESCALATION = AUTO ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql index b0fe6b6fd1..0e203e59a2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql @@ -1,54 +1,12 @@ -EXECUTE sp_rename 'ReferenceSearchParam', 'ReferenceSearchParamTbl' -GO -CREATE OR ALTER VIEW dbo.ReferenceSearchParam +CREATE VIEW dbo.ReferenceSearchParam AS SELECT A.ResourceTypeId ,ResourceSurrogateId ,SearchParamId ,BaseUri ,ReferenceResourceTypeId - ,ReferenceResourceId = CASE WHEN A.ReferenceResourceId = '' THEN B.ResourceId ELSE A.ReferenceResourceId END + ,ReferenceResourceId = B.ResourceId ,ReferenceResourceVersion - FROM dbo.ReferenceSearchParamTbl A + FROM dbo.ReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt GO -CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamIns ON dbo.ReferenceSearchParam INSTEAD OF INSERT -AS -DECLARE @DummyTop bigint = 9223372036854775807 -BEGIN - INSERT INTO dbo.ReferenceSearchParamTbl - ( - ResourceTypeId - ,ResourceSurrogateId - ,SearchParamId - ,BaseUri - ,ReferenceResourceTypeId - ,ReferenceResourceIdInt - ,ReferenceResourceVersion - ) - SELECT A.ResourceTypeId - ,ResourceSurrogateId - ,SearchParamId - ,BaseUri - ,ReferenceResourceTypeId - ,B.ResourceIdInt - ,ReferenceResourceVersion - FROM (SELECT TOP (@DummyTop) * FROM Inserted) A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -END -GO -CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamUpd ON dbo.ReferenceSearchParam INSTEAD OF UPDATE -AS -BEGIN - RAISERROR('Generic updates are not supported via ReferenceSearchParam view',18,127) -END -GO -CREATE OR ALTER TRIGGER dbo.ReferenceSearchParamDel ON dbo.ReferenceSearchParam INSTEAD OF DELETE -AS -BEGIN - DELETE FROM A - FROM dbo.ReferenceSearchParamTbl A - WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -END -GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql index ec0d99b472..33cbc8100b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -1,53 +1,40 @@ CREATE VIEW dbo.Resource -AS -SELECT ResourceTypeId - ,ResourceSurrogateId +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId ,ResourceId + ,A.ResourceIdInt ,Version ,IsHistory ,IsDeleted ,RequestMethod - ,RawResource + ,B.RawResource ,IsRawResourceMetaSet ,SearchParamHash - ,TransactionId + ,TransactionId ,HistoryTransactionId - FROM dbo.ResourceHistory + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt UNION ALL -SELECT ResourceTypeId - ,ResourceSurrogateId +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId ,ResourceId + ,A.ResourceIdInt ,Version ,IsHistory ,IsDeleted ,RequestMethod - ,RawResource + ,B.RawResource ,IsRawResourceMetaSet ,SearchParamHash - ,TransactionId + ,TransactionId ,HistoryTransactionId - FROM dbo.ResourceCurrent -GO -CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT -AS -BEGIN - INSERT INTO dbo.RawResources - ( ResourceTypeId, ResourceSurrogateId, RawResource ) - SELECT ResourceTypeId, ResourceSurrogateId, RawResource - FROM Inserted - - INSERT INTO dbo.ResourceCurrentTbl - ( ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId - FROM Inserted - WHERE IsHistory = 0 - - INSERT INTO dbo.ResourceHistoryTbl - ( ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId - FROM Inserted - WHERE IsHistory = 1 -END + ,OffsetInFile + FROM dbo.HistoryResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt GO CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE AS @@ -64,7 +51,7 @@ BEGIN ,SearchParamHash = A.SearchParamHash ,HistoryTransactionId = A.HistoryTransactionId FROM Inserted A - JOIN dbo.ResourceCurrentTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId RETURN END @@ -74,7 +61,7 @@ BEGIN UPDATE B SET SearchParamHash = A.SearchParamHash FROM Inserted A - JOIN dbo.ResourceCurrentTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE A.IsHistory = 0 RETURN @@ -90,12 +77,12 @@ BEGIN RAISERROR('Generic updates are not supported via Resource view',18,127) DELETE FROM A - FROM dbo.ResourceCurrentTbl A + FROM dbo.CurrentResources A WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) - INSERT INTO dbo.ResourceHistoryTbl - ( ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceId, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile FROM Inserted WHERE IsHistory = 1 END @@ -104,11 +91,11 @@ CREATE TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE AS BEGIN DELETE FROM A - FROM dbo.ResourceCurrentTbl A + FROM dbo.CurrentResources A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) DELETE FROM A - FROM dbo.ResourceHistoryTbl A + FROM dbo.HistoryResources A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) DELETE FROM A diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs index 18c7e78268..0333152ade 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs @@ -79,7 +79,7 @@ public async Task RetriesOnConflict(int requestedExceptions) { await _fixture.SqlHelper.ExecuteSqlCmd("TRUNCATE TABLE EventLog"); await _fixture.SqlHelper.ExecuteSqlCmd(@$" -CREATE TRIGGER Resource_Trigger ON ResourceCurrentTbl FOR INSERT +CREATE TRIGGER Resource_Trigger ON CurrentResources FOR INSERT AS IF (SELECT count(*) FROM EventLog WHERE Process = 'MergeResources' AND Status = 'Error') < {requestedExceptions} INSERT INTO ResourceCurrentTbl SELECT * FROM inserted -- this will cause dup key exception which is treated as a conflict @@ -197,16 +197,16 @@ public async Task TimeTravel() private async Task UpdateResource(Patient patient) { var oldId = patient.Id; - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.ResourceTbl SET IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}') AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET IsHistory = 1 WHERE ResourceId = '{oldId}' AND Version = 1"); var newId = Guid.NewGuid().ToString(); patient.Id = newId; await Mediator.UpsertResourceAsync(patient.ToResourceElement()); // there is no control to keep history, so insert as new and update to old - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.ResourceTbl SET ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}'), Version = 2, IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}'), Version = 2, IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1"); newId = Guid.NewGuid().ToString(); patient.Id = newId; await Mediator.UpsertResourceAsync(patient.ToResourceElement()); // there is no control to keep history, so insert as new and update to old //// noramlly we do not allow update in place - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.ResourceCurrent SET ResourceId = '{oldId}', Version = 3 WHERE ResourceId = '{newId}' AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.CurrentResources SET ResourceId = '{oldId}', Version = 3 WHERE ResourceId = '{newId}' AND Version = 1"); } [Fact] From cc9400897e8afdc4a5b72b11fa7ee0d839be3c14 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 17 Oct 2024 19:16:41 -0700 Subject: [PATCH 005/111] Fix after merge --- .../PrimaryKeyRangeParameterQueryGenerator.cs | 8 +- .../ResourceIdParameterQueryGenerator.cs | 2 +- ...ourceSurrogateIdParameterQueryGenerator.cs | 2 +- .../ResourceTypeIdParameterQueryGenerator.cs | 4 +- .../QueryGenerators/SqlQueryGenerator.cs | 148 +++++++++--------- .../Search/HashingSqlQueryParameterManager.cs | 2 +- .../Features/Search/SqlServerSearchService.cs | 25 ++- 7 files changed, 94 insertions(+), 97 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs index 897fc9f55d..859c8fe83c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/PrimaryKeyRangeParameterQueryGenerator.cs @@ -24,9 +24,9 @@ public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpressio context.StringBuilder.AppendLine("("); using (context.StringBuilder.Indent()) { - VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.ResourceCurrent.ResourceTypeId, null, primaryKeyRange.CurrentValue.ResourceTypeId, includeInParameterHash: false); + VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.Resource.ResourceTypeId, null, primaryKeyRange.CurrentValue.ResourceTypeId, includeInParameterHash: false); context.StringBuilder.Append(" AND "); - VisitSimpleBinary(expression.BinaryOperator, context, VLatest.ResourceCurrent.ResourceSurrogateId, null, primaryKeyRange.CurrentValue.ResourceSurrogateId, includeInParameterHash: false); + VisitSimpleBinary(expression.BinaryOperator, context, VLatest.Resource.ResourceSurrogateId, null, primaryKeyRange.CurrentValue.ResourceSurrogateId, includeInParameterHash: false); bool first = true; for (short i = 0; i < primaryKeyRange.NextResourceTypeIds.Count; i++) @@ -37,7 +37,7 @@ public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpressio { context.StringBuilder.AppendLine(); context.StringBuilder.Append("OR "); - AppendColumnName(context, VLatest.ResourceCurrent.ResourceTypeId, (int?)null).Append(" IN ("); + AppendColumnName(context, VLatest.Resource.ResourceTypeId, (int?)null).Append(" IN ("); first = false; } else @@ -45,7 +45,7 @@ public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpressio context.StringBuilder.Append(", "); } - context.StringBuilder.Append(context.Parameters.AddParameter(VLatest.ResourceCurrent.ResourceTypeId, i, includeInHash: false)); + context.StringBuilder.Append(context.Parameters.AddParameter(VLatest.Resource.ResourceTypeId, i, includeInHash: false)); } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs index 73ad6d4f55..acdfadbbb6 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceIdParameterQueryGenerator.cs @@ -14,7 +14,7 @@ internal class ResourceIdParameterQueryGenerator : ResourceTableSearchParameterQ public override SearchParameterQueryGeneratorContext VisitString(StringExpression expression, SearchParameterQueryGeneratorContext context) { - VisitSimpleString(expression, context, VLatest.ResourceCurrent.ResourceId, expression.Value); + VisitSimpleString(expression, context, VLatest.Resource.ResourceId, expression.Value); return context; } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs index 4d7ea9863e..9f3c700a19 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceSurrogateIdParameterQueryGenerator.cs @@ -14,7 +14,7 @@ internal class ResourceSurrogateIdParameterQueryGenerator : ResourceTableSearchP public override SearchParameterQueryGeneratorContext VisitBinary(BinaryExpression expression, SearchParameterQueryGeneratorContext context) { - VisitSimpleBinary(expression.BinaryOperator, context, VLatest.ResourceCurrent.ResourceSurrogateId, expression.ComponentIndex, expression.Value, includeInParameterHash: false); + VisitSimpleBinary(expression.BinaryOperator, context, VLatest.Resource.ResourceSurrogateId, expression.ComponentIndex, expression.Value, includeInParameterHash: false); return context; } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs index 515099aac3..93527ebe1b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/ResourceTypeIdParameterQueryGenerator.cs @@ -22,7 +22,7 @@ public override SearchParameterQueryGeneratorContext VisitString(StringExpressio return context; } - return VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.ResourceCurrent.ResourceTypeId, expression.ComponentIndex, resourceTypeId); + return VisitSimpleBinary(BinaryOperator.Equal, context, VLatest.Resource.ResourceTypeId, expression.ComponentIndex, resourceTypeId); } public override SearchParameterQueryGeneratorContext VisitIn(InExpression expression, SearchParameterQueryGeneratorContext context) @@ -41,7 +41,7 @@ public override SearchParameterQueryGeneratorContext VisitIn(InExpression } } - return VisitSimpleIn(context, VLatest.ResourceCurrent.ResourceTypeId, resolvedResourceTypeIds); + return VisitSimpleIn(context, VLatest.Resource.ResourceTypeId, resolvedResourceTypeIds); } } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 4b1c993a42..9c81358844 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -187,22 +187,22 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions StringBuilder.Append("TOP (").Append(Parameters.AddParameter(context.MaxItemCount + 1, includeInHash: false)).Append(") "); } - StringBuilder.Append(VLatest.ResourceCurrent.ResourceTypeId, resourceTableAlias).Append(", ") - .Append(VLatest.ResourceCurrent.ResourceId, resourceTableAlias).Append(", ") - .Append(VLatest.ResourceCurrent.Version, resourceTableAlias).Append(", ") - .Append(VLatest.ResourceCurrent.IsDeleted, resourceTableAlias).Append(", ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).Append(", ") - .Append(VLatest.ResourceCurrent.RequestMethod, resourceTableAlias).Append(", "); + StringBuilder.Append(VLatest.Resource.ResourceTypeId, resourceTableAlias).Append(", ") + .Append(VLatest.Resource.ResourceId, resourceTableAlias).Append(", ") + .Append(VLatest.Resource.Version, resourceTableAlias).Append(", ") + .Append(VLatest.Resource.IsDeleted, resourceTableAlias).Append(", ") + .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).Append(", ") + .Append(VLatest.Resource.RequestMethod, resourceTableAlias).Append(", "); // If there's a table expression, use the previously selected bit, otherwise everything in the select is considered a match StringBuilder.Append(expression.SearchParamTableExpressions.Count > 0 ? "CAST(IsMatch AS bit) AS IsMatch, " : "CAST(1 AS bit) AS IsMatch, "); StringBuilder.Append(expression.SearchParamTableExpressions.Count > 0 ? "CAST(IsPartial AS bit) AS IsPartial, " : "CAST(0 AS bit) AS IsPartial, "); - StringBuilder.Append(VLatest.ResourceCurrent.IsRawResourceMetaSet, resourceTableAlias).Append(", "); + StringBuilder.Append(VLatest.Resource.IsRawResourceMetaSet, resourceTableAlias).Append(", "); - StringBuilder.Append(VLatest.ResourceCurrent.SearchParamHash, resourceTableAlias).Append(", "); + StringBuilder.Append(VLatest.Resource.SearchParamHash, resourceTableAlias).Append(", "); - StringBuilder.Append(VLatest.ResourceCurrent.RawResource, resourceTableAlias); + StringBuilder.Append(VLatest.Resource.RawResource, resourceTableAlias); StringBuilder.Append(", ").Append(VLatest.Resource.TransactionId, resourceTableAlias); StringBuilder.Append(", ").Append(VLatest.Resource.OffsetInFile, resourceTableAlias); @@ -217,14 +217,14 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions if (selectingFromResourceTable) { - StringBuilder.Append("FROM ").Append(VLatest.ResourceCurrent).Append(" ").AppendLine(resourceTableAlias); + StringBuilder.Append("FROM ").Append(VLatest.Resource).Append(" ").AppendLine(resourceTableAlias); if (expression.SearchParamTableExpressions.Count > 0) { StringBuilder.Append(_joinShift).Append("JOIN ").Append(TableExpressionName(_tableExpressionCounter)); StringBuilder.Append(" ON ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).Append(".T1 AND ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).AppendLine(".Sid1"); + .Append(VLatest.Resource.ResourceTypeId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).Append(".T1 AND ") + .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).Append(" = ").Append(TableExpressionName(_tableExpressionCounter)).AppendLine(".Sid1"); } using (var delimitedClause = StringBuilder.BeginDelimitedWhereClause()) @@ -256,8 +256,8 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions { Column column = sort.searchParameterInfo.Name switch { - SearchParameterNames.ResourceType => VLatest.ResourceCurrent.ResourceTypeId, - SearchParameterNames.LastUpdated => VLatest.ResourceCurrent.ResourceSurrogateId, + SearchParameterNames.ResourceType => VLatest.Resource.ResourceTypeId, + SearchParameterNames.LastUpdated => VLatest.Resource.ResourceSurrogateId, _ => throw new InvalidOperationException($"Unexpected sort parameter {sort.searchParameterInfo.Name}"), }; sb.Append(column, resourceTableAlias).Append(" ").Append(sort.sortOrder == SortOrder.Ascending ? "ASC" : "DESC"); @@ -270,12 +270,12 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions .Append(TableExpressionName(_tableExpressionCounter)) .Append(".SortValue ") .Append(searchOptions.Sort[0].sortOrder == SortOrder.Ascending ? "ASC" : "DESC").Append(", ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); + .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); } else { StringBuilder - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); + .Append(VLatest.Resource.ResourceSurrogateId, resourceTableAlias).AppendLine(" ASC "); } AddOptionClause(); @@ -405,8 +405,8 @@ private void HandleParamTableUnion(SearchParamTableExpression searchParamTableEx StringBuilder.Append(TableExpressionName(++_tableExpressionCounter)).AppendLine(" AS").AppendLine("("); StringBuilder.Append("SELECT ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1"); + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1"); var searchParameterExpressionPredicate = searchParamTableExpression.Predicate as SearchParameterExpression; @@ -414,7 +414,7 @@ private void HandleParamTableUnion(SearchParamTableExpression searchParamTableEx if (searchParameterExpressionPredicate != null && searchParameterExpressionPredicate.Parameter.ColumnLocation().HasFlag(SearchParameterColumnLocation.ResourceTable)) { - StringBuilder.Append("FROM ").AppendLine(new VLatest.ResourceCurrentTable()); + StringBuilder.Append("FROM ").AppendLine(new VLatest.ResourceTable()); } else { @@ -445,8 +445,8 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx if (!IsInSortMode(context) || predecessorIndex < 0) { StringBuilder.Append("SELECT ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1") + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); } else @@ -454,13 +454,13 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx // we are in sort mode and we need to join with previous cte to propagate the SortValue var cte = TableExpressionName(predecessorIndex); StringBuilder.Append("SELECT ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" AS Sid1, ") + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).Append(" AS Sid1, ") .Append(cte).AppendLine(".SortValue") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table) .Append(_joinShift).Append("JOIN ").Append(cte) - .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); + .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); } } else if (searchParamTableExpression.ChainLevel == 1 && _unionVisited) @@ -472,16 +472,16 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx if (searchParameterExpressionPredicate != null && searchParameterExpressionPredicate.Parameter.ColumnLocation().HasFlag(SearchParameterColumnLocation.ResourceTable)) { - tableName = new VLatest.ResourceCurrentTable(); + tableName = new VLatest.ResourceTable(); } StringBuilder.Append("SELECT T1, Sid1, ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T2, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid2") + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T2, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid2") .Append("FROM ").AppendLine(tableName) .Append(_joinShift).Append("JOIN ").Append(TableExpressionName(FindRestrictingPredecessorTableExpressionIndex())) - .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append(_firstChainAfterUnionVisited ? "T2" : "T1") - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").AppendLine(_firstChainAfterUnionVisited ? "Sid2" : "Sid1"); + .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(_firstChainAfterUnionVisited ? "T2" : "T1") + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").AppendLine(_firstChainAfterUnionVisited ? "Sid2" : "Sid1"); // once we have visited a table after the union all, the remained of the inner joins // should be on T1 and Sid1 @@ -490,12 +490,12 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx else { StringBuilder.Append("SELECT T1, Sid1, ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T2, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid2") + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T2, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid2") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table) .Append(_joinShift).Append("JOIN ").Append(TableExpressionName(FindRestrictingPredecessorTableExpressionIndex())) - .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append("T2") - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").AppendLine("Sid2"); + .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append("T2") + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").AppendLine("Sid2"); } if (UseAppendWithJoin() @@ -533,12 +533,12 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre { var cte = TableExpressionName(predecessorIndex); StringBuilder.Append("SELECT ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1") // SELECT and FROM can be on same line only for singe line statements - .Append("FROM ").AppendLine(VLatest.ResourceCurrent) + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") // SELECT and FROM can be on same line only for singe line statements + .Append("FROM ").AppendLine(VLatest.Resource) .Append(_joinShift).Append("JOIN ").Append(cte) - .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); + .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -554,9 +554,9 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre else { StringBuilder.Append("SELECT ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).AppendLine(" AS Sid1") - .Append("FROM ").AppendLine(VLatest.ResourceCurrent); + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") + .Append("FROM ").AppendLine(VLatest.Resource); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -580,7 +580,7 @@ private void HandleTableKindNotExists(SearchParamTableExpression searchParamTabl using (StringBuilder.Indent()) { - StringBuilder.Append("SELECT ").AppendLine(VLatest.ResourceCurrent.ResourceSurrogateId, null) + StringBuilder.Append("SELECT ").AppendLine(VLatest.Resource.ResourceSurrogateId, null) .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -679,21 +679,21 @@ private void HandleTableKindChain( } StringBuilder - .Append(VLatest.ResourceCurrent.ResourceTypeId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").Append(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "T1, " : "T2, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") + .Append(VLatest.Resource.ResourceTypeId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").Append(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "T1, " : "T2, ") + .Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") .Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(VLatest.ResourceCurrent).Append(' ').Append(referenceTargetResourceTableAlias) - .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceTargetResourceTableAlias) - .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.ResourceCurrent.ResourceId, referenceTargetResourceTableAlias); + .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) + .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); // For reverse chaining, if there is a parameter on the _id search parameter, we need another join to get the resource ID of the reference source (all we have is the surrogate ID at this point) bool expressionOnTargetHandledBySecondJoin = chainedExpression.ExpressionOnTarget != null && chainedExpression.Reversed && chainedExpression.ExpressionOnTarget.AcceptVisitor(ExpressionContainsParameterVisitor.Instance, SearchParameterNames.Id); if (expressionOnTargetHandledBySecondJoin) { const string referenceSourceResourceTableAlias = "refSourceResource"; - StringBuilder.Append(_joinShift).Append("JOIN ").Append(VLatest.ResourceCurrent).Append(' ').Append(referenceSourceResourceTableAlias) - .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceSourceResourceTableAlias) - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, referenceSourceResourceTableAlias) + StringBuilder.Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) + .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceSourceResourceTableAlias) + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceResourceTableAlias) .Append(" AND "); chainedExpression.ExpressionOnTarget.AcceptVisitor(ResourceTableSearchParameterQueryGenerator.Instance, GetContext(referenceSourceResourceTableAlias)); StringBuilder.AppendLine(); @@ -702,8 +702,8 @@ private void HandleTableKindChain( if (searchParamTableExpression.ChainLevel > 1) { StringBuilder.Append(_joinShift).Append("JOIN ").Append(TableExpressionName(FindRestrictingPredecessorTableExpressionIndex())) - .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").Append("T2") - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").AppendLine("Sid2"); + .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").Append("T2") + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias).Append(" = ").AppendLine("Sid2"); } // since we are in chain table expression, we know the Table is the ReferenceSearchParam table @@ -774,14 +774,14 @@ private void HandleTableKindInclude( var table = !includeExpression.Reversed ? referenceTargetResourceTableAlias : referenceSourceTableAlias; - StringBuilder.Append(VLatest.ResourceCurrent.ResourceTypeId, table).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, table) + StringBuilder.Append(VLatest.Resource.ResourceTypeId, table).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, table) .AppendLine(" AS Sid1, 0 AS IsMatch "); StringBuilder.Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(VLatest.ResourceCurrent).Append(' ').Append(referenceTargetResourceTableAlias) - .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.ResourceCurrent.ResourceTypeId, referenceTargetResourceTableAlias) - .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.ResourceCurrent.ResourceId, referenceTargetResourceTableAlias); + .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) + .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -880,8 +880,8 @@ private void HandleTableKindInclude( } delimited.BeginDelimitedElement().Append("EXISTS (SELECT * FROM ").Append(fromCte) - .Append(" WHERE ").Append(VLatest.ResourceCurrent.ResourceTypeId, table).Append(" = T1 AND ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, table).Append(" = Sid1"); + .Append(" WHERE ").Append(VLatest.Resource.ResourceTypeId, table).Append(" = T1 AND ") + .Append(VLatest.Resource.ResourceSurrogateId, table).Append(" = Sid1"); if (!includeExpression.Iterate) { @@ -1034,8 +1034,8 @@ private void HandleTableKindSort(SearchParamTableExpression searchParamTableExpr if (!string.IsNullOrEmpty(sortContext.SortColumnName) && searchParamTableExpression.QueryGenerator != null) { StringBuilder.Append("SELECT ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" AS Sid1, ") + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).Append(" AS Sid1, ") .Append(sortContext.SortColumnName, null).AppendLine(" AS SortValue") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); @@ -1062,7 +1062,7 @@ private void HandleTableKindSort(SearchParamTableExpression searchParamTableExpr delimited.BeginDelimitedElement(); StringBuilder.Append("((").Append(sortContext.SortColumnName, null).Append(" = ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)); - StringBuilder.Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.ResourceCurrent.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); + StringBuilder.Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.Resource.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); StringBuilder.Append(" OR ").Append(sortContext.SortColumnName, null).Append(" ").Append(sortOperand).Append(" ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)).AppendLine(")"); } @@ -1083,8 +1083,8 @@ private void HandleTableKindSortWithFilter(SearchParamTableExpression searchPara if (!string.IsNullOrEmpty(sortContext.SortColumnName) && searchParamTableExpression.QueryGenerator != null) { StringBuilder.Append("SELECT ") - .Append(VLatest.ResourceCurrent.ResourceTypeId, null).Append(" AS T1, ") - .Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" AS Sid1, ") + .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") + .Append(VLatest.Resource.ResourceSurrogateId, null).Append(" AS Sid1, ") .Append(sortContext.SortColumnName, null).AppendLine(" AS SortValue") .Append("FROM ").AppendLine(searchParamTableExpression.QueryGenerator.Table); @@ -1111,7 +1111,7 @@ private void HandleTableKindSortWithFilter(SearchParamTableExpression searchPara delimited.BeginDelimitedElement(); StringBuilder.Append("((").Append(sortContext.SortColumnName, null).Append(" = ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)); - StringBuilder.Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.ResourceCurrent.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); + StringBuilder.Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" > ").Append(Parameters.AddParameter(VLatest.Resource.ResourceSurrogateId, sortContext.ContinuationToken.ResourceSurrogateId, includeInHash: false)).Append(")"); StringBuilder.Append(" OR ").Append(sortContext.SortColumnName, null).Append(" ").Append(sortOperand).Append(" ").Append(Parameters.AddParameter(sortContext.SortColumnName, sortContext.SortValue, includeInHash: false)).AppendLine(")"); } @@ -1229,8 +1229,8 @@ private void AppendIntersectionWithPredecessor(IndentedStringBuilder.DelimitedSc bool intersectWithFirst = (searchParamTableExpression.Kind == SearchParamTableExpressionKind.Chain ? searchParamTableExpression.ChainLevel - 1 : searchParamTableExpression.ChainLevel) == 0; StringBuilder.Append("EXISTS (SELECT * FROM ").Append(TableExpressionName(predecessorIndex)) - .Append(" WHERE ").Append(VLatest.ResourceCurrent.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") + .Append(" WHERE ").Append(VLatest.Resource.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") .Append(')'); } } @@ -1247,8 +1247,8 @@ private void AppendIntersectionWithPredecessorUsingInnerJoin(IndentedStringBuild // rather than an EXISTS clause. We have see that this significanlty reduces the query plan generation time for // complex queries sb.Append(_joinShift).Append("JOIN " + TableExpressionName(predecessorIndex - 0)) - .Append(" ON ").Append(VLatest.ResourceCurrent.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") - .Append(" AND ").Append(VLatest.ResourceCurrent.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") + .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, tableAlias).Append(" = ").Append(intersectWithFirst ? "T1" : "T2") + .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, tableAlias).Append(" = ").Append(intersectWithFirst ? "Sid1" : "Sid2") .AppendLine(); } } @@ -1299,12 +1299,12 @@ private void AppendDeletedClause(in IndentedStringBuilder.DelimitedScope delimit if (resourceVersionType.HasFlag(ResourceVersionType.Latest) && !resourceVersionType.HasFlag(ResourceVersionType.SoftDeleted)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.ResourceCurrent.IsDeleted, tableAlias).Append(" = 0 "); + StringBuilder.Append(VLatest.Resource.IsDeleted, tableAlias).Append(" = 0 "); } else if (resourceVersionType.HasFlag(ResourceVersionType.SoftDeleted) && !resourceVersionType.HasFlag(ResourceVersionType.Latest)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.ResourceCurrent.IsDeleted, tableAlias).Append(" = 1 "); + StringBuilder.Append(VLatest.Resource.IsDeleted, tableAlias).Append(" = 1 "); } } @@ -1318,12 +1318,12 @@ private void AppendHistoryClause(in IndentedStringBuilder.DelimitedScope delimit if (resourceVersionType.HasFlag(ResourceVersionType.Latest) && !resourceVersionType.HasFlag(ResourceVersionType.History)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.ResourceCurrent.IsHistory, tableAlias).Append(" = 0 "); + StringBuilder.Append(VLatest.Resource.IsHistory, tableAlias).Append(" = 0 "); } else if (resourceVersionType.HasFlag(ResourceVersionType.History) && !resourceVersionType.HasFlag(ResourceVersionType.Latest)) { delimited.BeginDelimitedElement(); - StringBuilder.Append(VLatest.ResourceCurrent.IsHistory, tableAlias).Append(" = 1 "); + StringBuilder.Append(VLatest.Resource.IsHistory, tableAlias).Append(" = 1 "); } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs index bebe4b1f26..46fbce6cc1 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/HashingSqlQueryParameterManager.cs @@ -63,7 +63,7 @@ public object AddParameter(Column column, T value, bool includeInHash) /// SQL parameter or input value depending on whether input was added to the list of parameters. public object AddParameter(Column column, object value, bool includeInHash) { - if (column.Metadata.Name == VLatest.ResourceCurrent.ResourceTypeId.Metadata.Name // logic uses "ResourceTypeId" string value. Resource table is chosen arbitrarily. + if (column.Metadata.Name == VLatest.Resource.ResourceTypeId.Metadata.Name // logic uses "ResourceTypeId" string value. Resource table is chosen arbitrarily. || column.Metadata.Name == VLatest.ReferenceSearchParam.ReferenceResourceTypeId.Metadata.Name || column.Metadata.Name == VLatest.TokenSearchParam.SearchParamId.Metadata.Name) // logic uses "SearchParamId" string value. We don't have cross table column sharing concept yet, so to avoid hardcoding TokenSearchParam is arbitrarily chosen. { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 35fbb8e78c..ae30cde8ab 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -380,9 +380,6 @@ await _sqlRetryService.ExecuteSql( sqlCommand.CommandType = CommandType.StoredProcedure; } - // Put "union" view - queryText = queryText.Replace("dbo.ResourceCurrent", "dbo.Resource", StringComparison.InvariantCulture); - // Command text contains no direct user input. #pragma warning disable CA2100 // Review SQL queries for security vulnerabilities sqlCommand.CommandText = queryText; @@ -847,21 +844,21 @@ private void ReadWrapper( out int? offsetInFile, out bool isInvisible) { - resourceTypeId = reader.Read(VLatest.ResourceCurrent.ResourceTypeId, 0); - resourceId = reader.Read(VLatest.ResourceCurrent.ResourceId, 1); - version = reader.Read(VLatest.ResourceCurrent.Version, 2); - isDeleted = reader.Read(VLatest.ResourceCurrent.IsDeleted, 3); - resourceSurrogateId = reader.Read(VLatest.ResourceCurrent.ResourceSurrogateId, 4); - requestMethod = reader.Read(VLatest.ResourceCurrent.RequestMethod, 5); + resourceTypeId = reader.Read(VLatest.Resource.ResourceTypeId, 0); + resourceId = reader.Read(VLatest.Resource.ResourceId, 1); + version = reader.Read(VLatest.Resource.Version, 2); + isDeleted = reader.Read(VLatest.Resource.IsDeleted, 3); + resourceSurrogateId = reader.Read(VLatest.Resource.ResourceSurrogateId, 4); + requestMethod = reader.Read(VLatest.Resource.RequestMethod, 5); isMatch = reader.Read(_isMatch, 6); isPartialEntry = reader.Read(_isPartial, 7); - isRawResourceMetaSet = reader.Read(VLatest.ResourceCurrent.IsRawResourceMetaSet, 8); - searchParameterHash = reader.Read(VLatest.ResourceCurrent.SearchParamHash, 9); + isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 8); + searchParameterHash = reader.Read(VLatest.Resource.SearchParamHash, 9); rawResourceSqlBytes = reader.GetSqlBytes(10); - transactionId = reader.Read(VLatest.ResourceCurrent.TransactionId, 11); - offsetInFile = reader.Read(VLatest.ResourceCurrent.OffsetInFile, 12); + transactionId = reader.Read(VLatest.Resource.TransactionId, 11); + offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, 12); isInvisible = false; - if (rawResourceSqlBytes != null) + if (!rawResourceSqlBytes.IsNull) { var rawResourceBytes = rawResourceSqlBytes.Value; if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) From d6ce380be0e356c9754f86bf0205154c5d4f7386 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 18 Oct 2024 09:10:47 -0700 Subject: [PATCH 006/111] adjustments --- .../Features/Schema/Migrations/84.sql | 203 +++++++++++------- .../Schema/Sql/Sprocs/GetResources.sql | 8 +- .../Schema/Sql/Sprocs/MergeResources.sql | 10 +- .../Sql/Sprocs/UpdateResourceSearchParams.sql | 11 +- .../Features/Schema/Sql/Tables/Resource.sql | 6 +- .../Schema/Sql/Views/ReferenceSearchParam.sql | 8 + .../Features/Schema/Sql/Views/Resource.sql | 39 +++- .../Persistence/FhirStorageTests.cs | 15 +- 8 files changed, 202 insertions(+), 98 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index bdfc970f31..93a420e0fa 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -661,23 +661,20 @@ DROP TABLE dbo.Resource; GO CREATE TABLE dbo.CurrentResources ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - ResourceIdInt BIGINT NOT NULL, - Version INT NOT NULL, - IsHistory BIT CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0 NOT NULL, - IsDeleted BIT NOT NULL, - RequestMethod VARCHAR (10) NULL, - RawResource VARBINARY (MAX) NULL, - IsRawResourceMetaSet BIT CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, - SearchParamHash VARCHAR (64) NULL, - TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL, - OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + IsHistory BIT CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0 NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), - CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_CurrentResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL - OR OffsetInFile IS NOT NULL) + CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ); ALTER TABLE dbo.CurrentResources SET (LOCK_ESCALATION = AUTO); @@ -693,23 +690,20 @@ CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_N GO CREATE TABLE dbo.HistoryResources ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - ResourceIdInt BIGINT NOT NULL, - Version INT NOT NULL, - IsHistory BIT CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1 NOT NULL, - IsDeleted BIT NOT NULL, - RequestMethod VARCHAR (10) NULL, - RawResource VARBINARY (MAX) NULL, - IsRawResourceMetaSet BIT CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, - SearchParamHash VARCHAR (64) NULL, - TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL, - OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + IsHistory BIT CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1 NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1), - CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_HistoryResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL - OR OffsetInFile IS NOT NULL) + CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ); ALTER TABLE dbo.HistoryResources SET (LOCK_ESCALATION = AUTO); @@ -2888,7 +2882,7 @@ BEGIN TRY UNION ALL SELECT B.ResourceTypeId, B.ResourceId, - ResourceSurrogateId, + C.ResourceSurrogateId, C.Version, IsDeleted, IsHistory, @@ -2907,12 +2901,17 @@ BEGIN TRY INNER LOOP JOIN dbo.CurrentResources AS C ON C.ResourceTypeId = A.ResourceTypeId - AND C.ResourceIdInt = B.ResourceIdInt) AS A + AND C.ResourceIdInt = B.ResourceIdInt + AND C.IsHistory = 0 + LEFT OUTER JOIN + dbo.RawResources AS D + ON D.ResourceTypeId = A.ResourceTypeId + AND D.ResourceSurrogateId = C.ResourceSurrogateId) AS A OPTION (MAXDOP 1); ELSE SELECT B.ResourceTypeId, B.ResourceId, - ResourceSurrogateId, + C.ResourceSurrogateId, C.Version, IsDeleted, IsHistory, @@ -2931,6 +2930,10 @@ BEGIN TRY dbo.CurrentResources AS C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN + dbo.RawResources AS D + ON D.ResourceTypeId = A.ResourceTypeId + AND D.ResourceSurrogateId = C.ResourceSurrogateId OPTION (MAXDOP 1); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; END TRY @@ -3767,7 +3770,8 @@ BEGIN TRY INNER JOIN dbo.Resource AS B ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId) + AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0) BEGIN BEGIN TRANSACTION; INSERT INTO @Existing (ResourceTypeId, SurrogateId) @@ -3947,7 +3951,7 @@ BEGIN TRY AND SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; END - INSERT INTO dbo.CurrentResources (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile) + INSERT INTO dbo.Resource (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile) SELECT ResourceTypeId, ResourceIdInt, Version, @@ -3960,24 +3964,7 @@ BEGIN TRY SearchParamHash, @TransactionId, OffsetInFile - FROM @ResourcesWithIds - WHERE IsHistory = 0; - SET @AffectedRows += @@rowcount; - INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile) - SELECT ResourceTypeId, - ResourceIdInt, - Version, - IsHistory, - ResourceSurrogateId, - IsDeleted, - RequestMethod, - RawResource, - IsRawResourceMetaSet, - SearchParamHash, - @TransactionId, - OffsetInFile - FROM @ResourcesWithIds - WHERE IsHistory = 1; + FROM @ResourcesWithIds; SET @AffectedRows += @@rowcount; INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) SELECT ResourceSurrogateId, @@ -5261,7 +5248,7 @@ BEGIN TRY dbo.ResourceWriteClaim AS B ON B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B - FROM dbo.ReferenceSearchParam AS B + FROM dbo.ReferenceSearchParams AS B WHERE EXISTS (SELECT * FROM @Ids AS A WHERE A.ResourceTypeId = B.ResourceTypeId @@ -5349,15 +5336,19 @@ BEGIN TRY ClaimTypeId, ClaimValue FROM @ResourceWriteClaims; - INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) - SELECT ResourceTypeId, + INSERT INTO dbo.ReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - ReferenceResourceId, + B.ResourceIdInt, ReferenceResourceVersion - FROM @ReferenceSearchParams; + FROM @ReferenceSearchParams AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ReferenceResourceId; INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) SELECT ResourceTypeId, ResourceSurrogateId, @@ -5545,6 +5536,20 @@ FROM dbo.ReferenceSearchParams AS A ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt; + +GO +CREATE TRIGGER dbo.ReferenceSearchParamDel + ON dbo.ReferenceSearchParam + INSTEAD OF DELETE + AS BEGIN + DELETE A + FROM dbo.ReferenceSearchParams AS A + WHERE EXISTS (SELECT * + FROM Deleted AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId); + END + GO CREATE VIEW dbo.Resource AS @@ -5597,6 +5602,48 @@ FROM dbo.HistoryResources AS A AND C.ResourceIdInt = A.ResourceIdInt; +GO +CREATE TRIGGER dbo.ResourceIns + ON dbo.Resource + INSTEAD OF INSERT + AS BEGIN + INSERT INTO dbo.RawResources (ResourceTypeId, ResourceSurrogateId, RawResource) + SELECT ResourceTypeId, + ResourceSurrogateId, + RawResource + FROM Inserted + WHERE RawResource IS NOT NULL; + INSERT INTO dbo.CurrentResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile) + SELECT ResourceTypeId, + ResourceSurrogateId, + ResourceIdInt, + Version, + IsDeleted, + RequestMethod, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId, + OffsetInFile + FROM Inserted + WHERE IsHistory = 0; + INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile) + SELECT ResourceTypeId, + ResourceSurrogateId, + ResourceIdInt, + Version, + IsDeleted, + RequestMethod, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId, + OffsetInFile + FROM Inserted + WHERE IsHistory = 1; + END + + GO CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource @@ -5615,6 +5662,13 @@ CREATE TRIGGER dbo.ResourceUpd dbo.RawResources AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; + IF @@rowcount = 0 + INSERT INTO dbo.RawResources (ResourceTypeId, ResourceSurrogateId, RawResource) + SELECT ResourceTypeId, + ResourceSurrogateId, + RawResource + FROM Inserted + WHERE RawResource IS NOT NULL; UPDATE B SET IsDeleted = A.IsDeleted, SearchParamHash = A.SearchParamHash, @@ -5640,13 +5694,22 @@ CREATE TRIGGER dbo.ResourceUpd RETURN; END IF UPDATE (RawResource) - UPDATE B - SET RawResource = A.RawResource - FROM Inserted AS A - INNER JOIN - dbo.RawResources AS B - ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId; + BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted AS A + INNER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + IF @@rowcount = 0 + INSERT INTO dbo.RawResources (ResourceTypeId, ResourceSurrogateId, RawResource) + SELECT ResourceTypeId, + ResourceSurrogateId, + RawResource + FROM Inserted + WHERE RawResource IS NOT NULL; + END IF NOT UPDATE (IsHistory) RAISERROR ('Generic updates are not supported via Resource view', 18, 127); DELETE A @@ -5697,11 +5760,7 @@ CREATE TRIGGER dbo.ResourceDel WHERE EXISTS (SELECT * FROM Deleted AS B WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId) - AND NOT EXISTS (SELECT * - FROM Resource AS B - WHERE B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId); + AND B.ResourceSurrogateId = A.ResourceSurrogateId); END GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index af534fc223..310b27dece 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -52,7 +52,7 @@ BEGIN TRY UNION ALL SELECT B.ResourceTypeId ,B.ResourceId - ,ResourceSurrogateId + ,C.ResourceSurrogateId ,C.Version ,IsDeleted ,IsHistory @@ -63,13 +63,14 @@ BEGIN TRY ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId ) A OPTION (MAXDOP 1) ELSE SELECT B.ResourceTypeId ,B.ResourceId - ,ResourceSurrogateId + ,C.ResourceSurrogateId ,C.Version ,IsDeleted ,IsHistory @@ -81,6 +82,7 @@ BEGIN TRY FROM (SELECT * FROM @ResourceKeys) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 4b717476b7..b63c7c582c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -324,18 +324,10 @@ BEGIN TRY --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' END - INSERT INTO dbo.CurrentResources + INSERT INTO dbo.Resource ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile ) SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, OffsetInFile FROM @ResourcesWithIds - WHERE IsHistory = 0 - SET @AffectedRows += @@rowcount - - INSERT INTO dbo.HistoryResources - ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile ) - SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, OffsetInFile - FROM @ResourcesWithIds - WHERE IsHistory = 1 SET @AffectedRows += @@rowcount INSERT INTO dbo.ResourceWriteClaim diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql index caabda7842..fdee25590e 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql @@ -39,7 +39,7 @@ BEGIN TRY -- First, delete all the search params of the resources to reindex. DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM dbo.ReferenceSearchParam B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + DELETE FROM B FROM dbo.ReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId @@ -60,10 +60,11 @@ BEGIN TRY SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims - INSERT INTO dbo.ReferenceSearchParam - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) - SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion - FROM @ReferenceSearchParams + INSERT INTO dbo.ReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, B.ResourceIdInt, ReferenceResourceVersion + FROM @ReferenceSearchParams A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ReferenceResourceId INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql index 1ccc3caff9..61afd3b2da 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql @@ -49,7 +49,6 @@ CREATE TABLE dbo.CurrentResources ,IsHistory bit NOT NULL CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL - ,RawResource varbinary(max) NULL ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL @@ -58,7 +57,7 @@ CREATE TABLE dbo.CurrentResources CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - ,CONSTRAINT CH_CurrentResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) + --,CONSTRAINT CH_CurrentResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) ) ALTER TABLE dbo.CurrentResources SET ( LOCK_ESCALATION = AUTO ) @@ -75,7 +74,6 @@ CREATE TABLE dbo.HistoryResources ,IsHistory bit NOT NULL CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1, CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL - ,RawResource varbinary(max) NULL ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL @@ -84,7 +82,7 @@ CREATE TABLE dbo.HistoryResources CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - ,CONSTRAINT CH_HistoryResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) + --,CONSTRAINT CH_HistoryResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) ) ALTER TABLE dbo.HistoryResources SET ( LOCK_ESCALATION = AUTO ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql index 0e203e59a2..933314186d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql @@ -10,3 +10,11 @@ SELECT A.ResourceTypeId FROM dbo.ReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt GO +CREATE TRIGGER dbo.ReferenceSearchParamDel ON dbo.ReferenceSearchParam INSTEAD OF DELETE +AS +BEGIN + DELETE FROM A + FROM dbo.ReferenceSearchParams A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql index 33cbc8100b..bc6a3c6f9c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -36,6 +36,28 @@ SELECT A.ResourceTypeId LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt GO +CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT +AS +BEGIN + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + + INSERT INTO dbo.CurrentResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile + FROM Inserted + WHERE IsHistory = 0 + + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile + FROM Inserted + WHERE IsHistory = 1 +END +GO CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE AS BEGIN @@ -46,6 +68,13 @@ BEGIN FROM Inserted A JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + IF @@rowcount = 0 + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + UPDATE B SET IsDeleted = A.IsDeleted ,SearchParamHash = A.SearchParamHash @@ -68,11 +97,20 @@ BEGIN END IF UPDATE(RawResource) -- invisible records + BEGIN UPDATE B SET RawResource = A.RawResource FROM Inserted A JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + IF @@rowcount = 0 + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + END + IF NOT UPDATE(IsHistory) RAISERROR('Generic updates are not supported via Resource view',18,127) @@ -101,6 +139,5 @@ BEGIN DELETE FROM A FROM dbo.RawResources A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) - AND NOT EXISTS (SELECT * FROM Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) END GO diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs index 0333152ade..3eb7e297db 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/FhirStorageTests.cs @@ -82,7 +82,7 @@ await _fixture.SqlHelper.ExecuteSqlCmd(@$" CREATE TRIGGER Resource_Trigger ON CurrentResources FOR INSERT AS IF (SELECT count(*) FROM EventLog WHERE Process = 'MergeResources' AND Status = 'Error') < {requestedExceptions} - INSERT INTO ResourceCurrentTbl SELECT * FROM inserted -- this will cause dup key exception which is treated as a conflict + INSERT INTO CurrentResources SELECT * FROM inserted -- this will cause dup key exception which is treated as a conflict "); var patient = (Patient)Samples.GetJsonSample("Patient").ToPoco(); @@ -197,16 +197,23 @@ public async Task TimeTravel() private async Task UpdateResource(Patient patient) { var oldId = patient.Id; - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET IsHistory = 1 WHERE ResourceId = '{oldId}' AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd(@$" +UPDATE dbo.Resource SET IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}') AND Version = 1 + "); var newId = Guid.NewGuid().ToString(); patient.Id = newId; await Mediator.UpsertResourceAsync(patient.ToResourceElement()); // there is no control to keep history, so insert as new and update to old - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.Resource SET ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}'), Version = 2, IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd(@$" +UPDATE dbo.Resource SET IsHistory = 1 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1 +UPDATE dbo.HistoryResources SET ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}'), Version = 2 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1 + "); newId = Guid.NewGuid().ToString(); patient.Id = newId; await Mediator.UpsertResourceAsync(patient.ToResourceElement()); // there is no control to keep history, so insert as new and update to old //// noramlly we do not allow update in place - await _fixture.SqlHelper.ExecuteSqlCmd($"UPDATE dbo.CurrentResources SET ResourceId = '{oldId}', Version = 3 WHERE ResourceId = '{newId}' AND Version = 1"); + await _fixture.SqlHelper.ExecuteSqlCmd(@$" +UPDATE dbo.CurrentResources SET ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{oldId}'), Version = 3 WHERE ResourceIdInt = (SELECT ResourceIdInt FROM ResourceIdIntMap WHERE ResourceId = '{newId}') AND Version = 1 + "); } [Fact] From 2950bcf1b6306e79515d190999d2a194ee8bf261 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 18 Oct 2024 10:48:11 -0700 Subject: [PATCH 007/111] tests --- .../SqlServerTransactionScopeTests.cs | 19 +++++++++++++------ .../Persistence/SqlServerWatchdogTests.cs | 2 +- 2 files changed, 14 insertions(+), 7 deletions(-) diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerTransactionScopeTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerTransactionScopeTests.cs index 38e8fe9fac..ea468222fb 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerTransactionScopeTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerTransactionScopeTests.cs @@ -43,9 +43,13 @@ public async Task GivenATransactionScope_WhenReading_TheUncommittedValuesShouldO using (SqlCommandWrapper sqlCommandWrapper = connectionWrapperWithTransaction.CreateRetrySqlCommand()) { sqlCommandWrapper.CommandText = @" - INSERT INTO Resource - (ResourceTypeId,ResourceId,Version,IsHistory,ResourceSurrogateId,IsDeleted,RequestMethod,RawResource,IsRawResourceMetaSet,SearchParamHash) - VALUES(97, @newId, 1, 0, 5095719085917680000, 0, null, CAST('test' AS VARBINARY(MAX)), 0, @searchParamHash)"; +INSERT INTO dbo.ResourceIdIntMap + (ResourceTypeId, ResourceIdInt,ResourceId) + SELECT 97,5095719085917680000, @newId +INSERT INTO dbo.Resource + (ResourceTypeId, ResourceIdInt,Version,IsHistory,ResourceSurrogateId,IsDeleted,IsRawResourceMetaSet, RawResource, SearchParamHash) + SELECT 97,5095719085917680000, 1, 0,5095719085917680000, 0, 0,CAST('test' AS varbinary(max)), @searchParamHash + "; sqlCommandWrapper.Parameters.Add(new SqlParameter { ParameterName = "newId", Value = newId }); sqlCommandWrapper.Parameters.Add(new SqlParameter { ParameterName = "searchParamHash", Value = searchParamHash }); @@ -97,9 +101,12 @@ public async Task GivenATransactionScope_WhenReadingAfterComplete_TheValuesShoul using (SqlCommandWrapper sqlCommandWrapper = connectionWrapperWithTransaction.CreateRetrySqlCommand()) { sqlCommandWrapper.CommandText = @" - INSERT INTO Resource - (ResourceTypeId,ResourceId,Version,IsHistory,ResourceSurrogateId,IsDeleted,RequestMethod,RawResource,IsRawResourceMetaSet,SearchParamHash) - VALUES(97, @newId, 1, 0, 5095719085917680001, 0, null, CAST('test' AS VARBINARY(MAX)), 0, @searchParamHash)"; +INSERT INTO dbo.ResourceIdIntMap + (ResourceTypeId, ResourceIdInt,ResourceId) + SELECT 97,5095719085917680001, @newId +INSERT INTO Resource + (ResourceTypeId, ResourceIdInt,Version,IsHistory,ResourceSurrogateId,IsDeleted, RawResource,IsRawResourceMetaSet, SearchParamHash) + SELECT 97,5095719085917680001, 1, 0,5095719085917680001, 0,CAST('test' AS varbinary(max)), 0,@searchParamHash"; sqlCommandWrapper.Parameters.Add(new SqlParameter { ParameterName = "newId", Value = newId }); sqlCommandWrapper.Parameters.Add(new SqlParameter { ParameterName = "searchParamHash", Value = searchParamHash }); diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs index a6291bb8e0..6ea158cc88 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerWatchdogTests.cs @@ -198,7 +198,7 @@ FOR INSERT Assert.Equal("Test", e.Message); } - Assert.Equal(1, GetCount("ResourceTbl")); // resource inserted + Assert.Equal(1, GetCount("Resource")); // resource inserted Assert.Equal(0, GetCount("NumberSearchParam")); // number is not inserted ExecuteSql("DROP TRIGGER dbo.tmp_NumberSearchParam"); From c3ccf6926eb1b28f7c61031de986d0c0332fddba Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 18 Oct 2024 13:27:08 -0700 Subject: [PATCH 008/111] Merge fixes --- .../Features/Search/SqlServerSearchService.cs | 4 +-- .../Storage/SqlRetry/SqlRetryService.cs | 29 ++++++++++--------- .../Features/Storage/SqlStoreClient.cs | 2 +- 3 files changed, 18 insertions(+), 17 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index f5e6cc9d46..7a3bcf6329 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -461,7 +461,7 @@ await _sqlRetryService.ExecuteSql( { rawResource = new Lazy(() => { - var decompressedResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); + var decompressedResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(resourceSurrogateId), resourceSurrogateId, nameof(resourceTypeId), resourceTypeId, decompressedResource.Length); @@ -664,7 +664,7 @@ await _sqlRetryService.ExecuteSql( continue; } - var rawResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); + var rawResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); if (string.IsNullOrEmpty(rawResource)) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs index d5e9c8118c..0014b61bf3 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlRetry/SqlRetryService.cs @@ -74,19 +74,19 @@ private readonly HashSet _transientErrors private static object _initLocker = new object(); private static EventLogHandler _eventLogHandler; private CoreFeatureConfiguration _coreFeatureConfiguration; - private readonly string _database; - - /// - /// Constructor that initializes this implementation of the ISqlRetryService interface. This class - /// is designed to operate as a standard .NET service and all of the parameters to the constructor are passed - /// using .NET dependency injection. - /// - /// Internal FHIR server interface used to create SqlConnection. - /// Internal FHIR server interface used initialize this class. - /// Initializes various retry parameters. - /// Initializes custom delegate that is used to examine if the thrown exception represent a retriable error. - /// Checks if SQL replicas are enabled - public SqlRetryService( + private readonly string _database; + + /// + /// Constructor that initializes this implementation of the ISqlRetryService interface. This class + /// is designed to operate as a standard .NET service and all of the parameters to the constructor are passed + /// using .NET dependency injection. + /// + /// Internal FHIR server interface used to create SqlConnection. + /// Internal FHIR server interface used initialize this class. + /// Initializes various retry parameters. + /// Initializes custom delegate that is used to examine if the thrown exception represent a retriable error. + /// Checks if SQL replicas are enabled + public SqlRetryService( ISqlConnectionBuilder sqlConnectionBuilder, IOptions sqlServerDataStoreConfiguration, IOptions sqlRetryServiceOptions, @@ -106,7 +106,8 @@ public SqlRetryService( { throw new ArgumentException("default database cannot be master"); } - _coreFeatureConfiguration = coreFeatureConfiguration.Value; + + _coreFeatureConfiguration = coreFeatureConfiguration.Value; if (sqlRetryServiceOptions.Value.RemoveTransientErrors != null) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 48fcf294d4..0c1b9bd826 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -32,7 +32,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Storage internal class SqlStoreClient { private readonly ISqlRetryService _sqlRetryService; - private readonly ILogger _logger; + private readonly ILogger _logger; internal const string InvisibleResource = " "; public SqlStoreClient(ISqlRetryService sqlRetryService, ILogger logger) From b0ed1eb11d5d4769aec2b2fee4db5caf83f875a4 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 18 Oct 2024 14:16:10 -0700 Subject: [PATCH 009/111] Ignore NULL reference resource tyoe --- .../Features/Schema/Migrations/84.sql | 4 +++- .../Features/Schema/Sql/Sprocs/MergeResources.sql | 2 +- 2 files changed, 4 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 93a420e0fa..679de75ca4 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -3634,7 +3634,9 @@ BEGIN TRY ReferenceResourceTypeId, isnull(C.ResourceIdInt, B.ResourceIdInt), ReferenceResourceVersion - FROM @ReferenceSearchParams AS A + FROM (SELECT * + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NOT NULL) AS A LEFT OUTER JOIN @InsertedIds AS B ON B.ResourceTypeId = A.ReferenceResourceTypeId diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index b63c7c582c..84b765ff53 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -121,7 +121,7 @@ BEGIN TRY INSERT INTO @ReferenceSearchParamsWithIds ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), ReferenceResourceVersion - FROM @ReferenceSearchParams A + FROM (SELECT * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL) A LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId -- Prepare id map for reference search params End --------------------------------------------------------------------------- From 51a942db2c7cba37a948db37e5952bc0ec8df6e9 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 18 Oct 2024 14:16:20 -0700 Subject: [PATCH 010/111] test fix --- .../Operations/Export/SqlServerExportTests.cs | 16 +++++++++++----- 1 file changed, 11 insertions(+), 5 deletions(-) diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs index e2d6833efb..1c91f9eb3e 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Features/Operations/Export/SqlServerExportTests.cs @@ -151,23 +151,29 @@ FOR INSERT private void PrepareData() { ExecuteSql("TRUNCATE TABLE dbo.JobQueue"); + ExecuteSql("DELETE FROM dbo.ResourceIdIntMap"); ExecuteSql("DELETE FROM dbo.Resource"); var surrId = DateTimeOffset.UtcNow.ToId(); ExecuteSql(@$" +INSERT INTO ResourceIdIntMap + (ResourceTypeId, ResourceId, ResourceIdInt) + SELECT ResourceTypeId, newid(), RowId + FROM (SELECT RowId FROM (SELECT RowId = row_number() OVER (ORDER BY A1.id) FROM syscolumns A1, syscolumns A2) A WHERE RowId <= 1000) A + CROSS JOIN (SELECT ResourceTypeId FROM dbo.ResourceType WHERE Name IN ('Patient','Observation','Claim')) B + INSERT INTO Resource - (ResourceTypeId,ResourceId,Version,IsHistory,ResourceSurrogateId,IsDeleted,RequestMethod,RawResource,IsRawResourceMetaSet,SearchParamHash) + (ResourceTypeId,ResourceIdInt,Version,IsHistory,ResourceSurrogateId,IsDeleted,RequestMethod,RawResource,IsRawResourceMetaSet,SearchParamHash) SELECT ResourceTypeId - ,newid() + ,ResourceIdInt ,1 ,0 - ,{surrId} - RowId * 1000 -- go to the past + ,{surrId} - ResourceIdInt * 1000 -- go to the past ,0 ,null ,0x12345 ,1 ,null - FROM (SELECT RowId FROM (SELECT RowId = row_number() OVER (ORDER BY A1.id) FROM syscolumns A1, syscolumns A2) A WHERE RowId <= 1000) A - CROSS JOIN (SELECT ResourceTypeId FROM dbo.ResourceType WHERE Name IN ('Patient','Observation','Claim')) B + FROM ResourceIdIntMap B "); } From 38e869bd96bada0d34a97ec7db8153d870b748ba Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 18 Oct 2024 21:00:09 -0700 Subject: [PATCH 011/111] default number of columns = 13 --- .../Features/Search/SqlServerSearchService.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 7a3bcf6329..ef9dea5faa 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -69,7 +69,7 @@ internal class SqlServerSearchService : SearchService private readonly SchemaInformation _schemaInformation; private readonly ICompressedRawResourceConverter _compressedRawResourceConverter; private readonly RequestContextAccessor _requestContextAccessor; - private const int _defaultNumberOfColumnsReadFromResult = 11; + private const int _defaultNumberOfColumnsReadFromResult = 13; private readonly SearchParameterInfo _fakeLastUpdate = new SearchParameterInfo(SearchParameterNames.LastUpdated, SearchParameterNames.LastUpdated); private readonly ISqlQueryHashCalculator _queryHashCalculator; private readonly IParameterStore _parameterStore; From bb535af54dd3c49f3ab0f06d0d7304eb46df989f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sat, 19 Oct 2024 15:52:59 -0700 Subject: [PATCH 012/111] commented 84 diff --- .../Features/Schema/Migrations/84.diff.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 2230e21194..0e3570f066 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -1 +1 @@ -SET TRANSACTION ISOLATION LEVEL READ COMMITTED -- Not sure that it matters, but to gurantee that SQL versioning is not used -- Disable defrag UPDATE Parameters SET Number = 0 WHERE Id = 'DefragWatchdog.IsEnabled' EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Update',@Rows=@@rowcount,@Text='disable defrag' GO IF (SELECT sum(reserved_page_count*8.0/1024/1024) FROM sys.dm_db_partition_stats) > 2500 -- skip for large databases BEGIN INSERT INTO dbo.Parameters (Id, Number) SELECT 'SkipHistorySeparation', 1 EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Insert',@Rows=@@rowcount,@Text='SkipHistorySeparation' END GO ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalStartId bigint = NULL, @GlobalEndId bigint = NULL AS set nocount on DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') +' S='+isnull(convert(varchar,@StartId),'NULL') +' E='+isnull(convert(varchar,@EndId),'NULL') +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') -- Could this just be a boolean for if historical records should be returned? GlobalEndId should equal EndId in all cases I can think of. ,@st datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 BEGIN TRY DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) IF @GlobalEndId IS NOT NULL -- snapshot view BEGIN INSERT INTO @ResourceIds SELECT DISTINCT ResourceId FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND IsHistory = 1 AND IsDeleted = 0 OPTION (MAXDOP 1) IF @@rowcount > 0 INSERT INTO @SurrogateIds SELECT ResourceSurrogateId FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) -- w/o hint access to Resource table is inefficient when many versions are present. Hint is ignored if Resource is a view. WHERE ResourceTypeId = @ResourceTypeId AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId ) A WHERE RowId = 1 AND ResourceSurrogateId BETWEEN @StartId AND @EndId OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) END SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND IsHistory = 0 AND IsDeleted = 0 UNION ALL SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 AND IsDeleted = 0 OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; THROW END CATCH GO ALTER PROCEDURE dbo.DequeueJob @QueueType tinyint, @Worker varchar(100), @HeartbeatTimeoutSec int, @InputJobId bigint = NULL, @CheckTimeoutJobs bit = 0 AS set nocount on DECLARE @SP varchar(100) = 'DequeueJob' ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') +' H='+isnull(convert(varchar,@HeartbeatTimeoutSec),'NULL') +' W='+isnull(@Worker,'NULL') +' IJ='+isnull(convert(varchar,@InputJobId),'NULL') +' T='+isnull(convert(varchar,@CheckTimeoutJobs),'NULL') ,@Rows int = 0 ,@st datetime = getUTCdate() ,@JobId bigint ,@msg varchar(100) ,@Lock varchar(100) ,@PartitionId tinyint ,@MaxPartitions tinyint = 16 -- !!! hardcoded ,@LookedAtPartitions tinyint = 0 BEGIN TRY IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'DequeueJobStop' AND Number = 1) BEGIN EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=0,@Text='Skipped' RETURN END IF @InputJobId IS NULL SET @PartitionId = @MaxPartitions * rand() ELSE SET @PartitionId = @InputJobId % 16 SET TRANSACTION ISOLATION LEVEL READ COMMITTED WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions AND @CheckTimeoutJobs = 0 BEGIN SET @Lock = 'DequeueJob_'+convert(varchar,@QueueType)+'_'+convert(varchar,@PartitionId) BEGIN TRANSACTION EXECUTE sp_getapplock @Lock, 'Exclusive' UPDATE T SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = 1 -- running ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = T.JobId FROM dbo.JobQueue T WITH (PAGLOCK) JOIN (SELECT TOP 1 JobId FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 0 ORDER BY Priority ,JobId ) S ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId SET @Rows += @@rowcount COMMIT TRANSACTION IF @JobId IS NULL BEGIN SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END SET @LookedAtPartitions = @LookedAtPartitions + 1 END END -- Do timed out items. SET @LookedAtPartitions = 0 WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions BEGIN SET @Lock = 'DequeueStoreCopyWorkUnit_'+convert(varchar, @PartitionId) BEGIN TRANSACTION EXECUTE sp_getapplock @Lock, 'Exclusive' UPDATE T SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = CASE WHEN CancelRequested = 0 THEN 1 ELSE 4 END ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = CASE WHEN CancelRequested = 0 THEN T.JobId END ,Info = convert(varchar(1000),isnull(Info,'')+' Prev: Worker='+Worker+' Start='+convert(varchar,StartDate,121)) FROM dbo.JobQueue T WITH (PAGLOCK) JOIN (SELECT TOP 1 JobId FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 1 AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec ORDER BY Priority ,JobId ) S ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId SET @Rows += @@rowcount COMMIT TRANSACTION IF @JobId IS NULL BEGIN SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END SET @LookedAtPartitions = @LookedAtPartitions + 1 END END IF @InputJobId IS NOT NULL BEGIN UPDATE dbo.JobQueue WITH (PAGLOCK) SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = 1 -- running ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = JobId WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 0 AND JobId = @InputJobId SET @Rows += @@rowcount IF @JobId IS NULL BEGIN UPDATE dbo.JobQueue WITH (PAGLOCK) SET StartDate = getUTCdate() ,HeartbeatDate = getUTCdate() ,Worker = @Worker ,Status = 1 -- running ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) ,@JobId = JobId WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 1 AND JobId = @InputJobId AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec SET @Rows += @@rowcount END END IF @JobId IS NOT NULL EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobId = @JobId SET @msg = 'J='+isnull(convert(varchar,@JobId),'NULL')+' P='+convert(varchar,@PartitionId) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows,@Text=@msg END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='DequeueJob',@Action='Alter' GO ALTER PROCEDURE dbo.GetActiveJobs @QueueType tinyint, @GroupId bigint = NULL AS set nocount on DECLARE @SP varchar(100) = 'GetActiveJobs' ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') +' G='+isnull(convert(varchar,@GroupId),'NULL') ,@st datetime = getUTCdate() ,@JobIds BigintList ,@PartitionId tinyint ,@MaxPartitions tinyint = 16 -- !!! hardcoded ,@LookedAtPartitions tinyint = 0 ,@Rows int = 0 BEGIN TRY SET @PartitionId = @MaxPartitions * rand() WHILE @LookedAtPartitions < @MaxPartitions BEGIN IF @GroupId IS NULL INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND Status IN (0,1) ELSE INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND GroupId = @GroupId AND Status IN (0,1) SET @Rows += @@rowcount SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END SET @LookedAtPartitions += 1 END IF @Rows > 0 EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='GetActiveJobs',@Action='Alter' GO INSERT INTO dbo.Parameters (Id, Char) SELECT 'HistorySeparation', 'LogEvent' EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Start' GO ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = 'GetResources' ,@InputRows int ,@DummyTop bigint = 9223372036854775807 ,@NotNullVersionExists bit ,@NullVersionExists bit ,@MinRT smallint ,@MaxRT smallint SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) BEGIN TRY IF @NotNullVersionExists = 1 IF @NullVersionExists = 0 SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) ELSE SELECT * FROM (SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 ) A OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) ELSE SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId ,B.Version ,IsDeleted ,IsHistory ,RawResource ,IsRawResourceMetaSet ,SearchParamHash FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='GetResources',@Action='Alter' GO ALTER PROCEDURE dbo.MergeResources -- This stored procedure can be used for: -- 1. Ordinary put with single version per resource in input -- 2. Put with history preservation (multiple input versions per resource) -- 3. Copy from one gen2 store to another with ResourceSurrogateId preserved. @AffectedRows int = 0 OUT ,@RaiseExceptionOnConflict bit = 1 ,@IsResourceChangeCaptureEnabled bit = 0 ,@TransactionId bigint = NULL ,@SingleTransaction bit = 1 ,@Resources dbo.ResourceList READONLY ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY ,@TokenSearchParams dbo.TokenSearchParamList READONLY ,@TokenTexts dbo.TokenTextList READONLY ,@StringSearchParams dbo.StringSearchParamList READONLY ,@UriSearchParams dbo.UriSearchParamList READONLY ,@NumberSearchParams dbo.NumberSearchParamList READONLY ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY ,@DateTimeSearchParms dbo.DateTimeSearchParamList READONLY ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) ,@DummyTop bigint = 9223372036854775807 ,@InitialTranCount int = @@trancount ,@IsRetry bit = 0 DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') SET @AffectedRows = 0 BEGIN TRY DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) DECLARE @ResourceInfos AS TABLE ( ResourceTypeId smallint NOT NULL ,SurrogateId bigint NOT NULL ,Version int NOT NULL ,KeepHistory bit NOT NULL ,PreviousVersion int NULL ,PreviousSurrogateId bigint NULL PRIMARY KEY (ResourceTypeId, SurrogateId) ) DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 SET @SingleTransaction = 1 SET @Mode += ' ST='+convert(varchar,@SingleTransaction) -- perform retry check in transaction to hold locks IF @InitialTranCount = 0 BEGIN IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 ) BEGIN BEGIN TRANSACTION INSERT INTO @Existing ( ResourceTypeId, SurrogateId ) SELECT B.ResourceTypeId, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * FROM @Resources) A JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @@rowcount > 0 SET @IsRetry = 1 IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction END END SET @Mode += ' R='+convert(varchar,@IsRetry) IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION IF @IsRetry = 0 BEGIN INSERT INTO @ResourceInfos ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * FROM @Resources WHERE HasVersionToCompare = 1) A LEFT OUTER JOIN dbo.Resource B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <> PreviousVersion + 1) THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 INSERT INTO @PreviousSurrogateIds SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory FROM @ResourceInfos WHERE PreviousSurrogateId IS NOT NULL IF @@rowcount > 0 BEGIN UPDATE dbo.Resource SET IsHistory = 1 WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) SET @AffectedRows += @@rowcount IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) UPDATE dbo.Resource SET IsHistory = 1 ,RawResource = 0xF -- "invisible" value ,SearchParamHash = NULL ,HistoryTransactionId = @TransactionId WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) ELSE DELETE FROM dbo.Resource WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) SET @AffectedRows += @@rowcount DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenText WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.StringSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.UriSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.NumberSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.QuantitySearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.DateTimeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.ReferenceTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenDateTimeCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenQuantityCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenStringCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' END INSERT INTO dbo.Resource ( ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId ) SELECT ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId FROM @Resources SET @AffectedRows += @@rowcount INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion FROM @ReferenceSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow FROM @TokenSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenText ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text FROM @TokenTexts SET @AffectedRows += @@rowcount INSERT INTO dbo.StringSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax FROM @StringSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.UriSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri FROM @UriSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.NumberSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue FROM @NumberSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.QuantitySearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue FROM @QuantitySearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.DateTimeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax FROM @DateTimeSearchParms SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 FROM @ReferenceTokenCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 FROM @TokenTokenCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenDateTimeCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 FROM @TokenDateTimeCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenQuantityCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 FROM @TokenQuantityCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenStringCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 FROM @TokenStringCompositeSearchParams SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenNumberNumberCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange FROM @TokenNumberNumberCompositeSearchParams SET @AffectedRows += @@rowcount END -- @IsRetry = 0 ELSE BEGIN -- @IsRetry = 1 INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM (SELECT TOP (@DummyTop) * FROM @ResourceWriteClaims) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.ResourceWriteClaim C WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow FROM (SELECT TOP (@DummyTop) * FROM @TokenSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenText ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text FROM (SELECT TOP (@DummyTop) * FROM @TokenTexts) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.StringSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax FROM (SELECT TOP (@DummyTop) * FROM @StringSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenText C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.UriSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri FROM (SELECT TOP (@DummyTop) * FROM @UriSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.UriSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.NumberSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue FROM (SELECT TOP (@DummyTop) * FROM @NumberSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.NumberSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.QuantitySearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue FROM (SELECT TOP (@DummyTop) * FROM @QuantitySearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.QuantitySearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.DateTimeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax FROM (SELECT TOP (@DummyTop) * FROM @DateTimeSearchParms) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.ReferenceTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 FROM (SELECT TOP (@DummyTop) * FROM @ReferenceTokenCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.DateTimeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 FROM (SELECT TOP (@DummyTop) * FROM @TokenTokenCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenTokenCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenDateTimeCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 FROM (SELECT TOP (@DummyTop) * FROM @TokenDateTimeCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenDateTimeCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenQuantityCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 FROM (SELECT TOP (@DummyTop) * FROM @TokenQuantityCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenQuantityCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenStringCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 FROM (SELECT TOP (@DummyTop) * FROM @TokenStringCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenStringCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount INSERT INTO dbo.TokenNumberNumberCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange FROM (SELECT TOP (@DummyTop) * FROM @TokenNumberNumberCompositeSearchParams) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * FROM dbo.TokenNumberNumberCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount END IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. EXECUTE dbo.CaptureResourceIdsForChanges @Resources IF @TransactionId IS NOT NULL EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows END TRY BEGIN CATCH IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource''%' OR error_message() LIKE '%''dbo.ResourceCurrent''%' OR error_message() LIKE '%''dbo.ResourceHistory''%') -- handles old and separated tables THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; ELSE THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='MergeResources',@Action='Alter' GO ALTER PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT ,@Resources dbo.ResourceList READONLY ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY ,@TokenSearchParams dbo.TokenSearchParamList READONLY ,@TokenTexts dbo.TokenTextList READONLY ,@StringSearchParams dbo.StringSearchParamList READONLY ,@UriSearchParams dbo.UriSearchParamList READONLY ,@NumberSearchParams dbo.NumberSearchParamList READONLY ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY ,@DateTimeSearchParams dbo.DateTimeSearchParamList READONLY ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') ,@Rows int BEGIN TRY DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) BEGIN TRANSACTION -- Update the search parameter hash value in the main resource table -- Avoid join to enable update via view UPDATE A SET SearchParamHash = (SELECT SearchParamHash FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) FROM dbo.Resource A WHERE IsHistory = 0 AND EXISTS (SELECT * FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) SET @Rows = @@rowcount -- First, delete all the search params of the resources to reindex. DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.ReferenceSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- Next, insert all the new search params. INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims INSERT INTO dbo.ReferenceSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion FROM @ReferenceSearchParams INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow FROM @TokenSearchParams INSERT INTO dbo.TokenText ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text FROM @TokenTexts INSERT INTO dbo.StringSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax FROM @StringSearchParams INSERT INTO dbo.UriSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri FROM @UriSearchParams INSERT INTO dbo.NumberSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue FROM @NumberSearchParams INSERT INTO dbo.QuantitySearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue FROM @QuantitySearchParams INSERT INTO dbo.DateTimeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax FROM @DateTimeSearchParams INSERT INTO dbo.ReferenceTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 FROM @ReferenceTokenCompositeSearchParams INSERT INTO dbo.TokenTokenCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 FROM @TokenTokenCompositeSearchParams INSERT INTO dbo.TokenDateTimeCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 FROM @TokenDateTimeCompositeSearchParams INSERT INTO dbo.TokenQuantityCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 FROM @TokenQuantityCompositeSearchParams INSERT INTO dbo.TokenStringCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 FROM @TokenStringCompositeSearchParams INSERT INTO dbo.TokenNumberNumberCompositeSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange FROM @TokenNumberNumberCompositeSearchParams COMMIT TRANSACTION SET @FailedResources = (SELECT count(*) FROM @Resources) - @Rows EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='UpdateResourceSearchParams',@Action='Alter' GO ALTER PROCEDURE dbo.DisableIndexes WITH EXECUTE AS 'dbo' AS set nocount on DECLARE @SP varchar(100) = 'DisableIndexes' ,@Mode varchar(200) = '' ,@st datetime = getUTCdate() ,@Tbl varchar(100) ,@Ind varchar(200) ,@Txt varchar(4000) BEGIN TRY EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start' DECLARE @Tables TABLE (Tbl varchar(100) PRIMARY KEY, Supported bit) INSERT INTO @Tables EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0 EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Tables',@Action='Insert',@Rows=@@rowcount DECLARE @Indexes TABLE (Tbl varchar(100), Ind varchar(200), TblId int, IndId int PRIMARY KEY (Tbl, Ind)) INSERT INTO @Indexes SELECT Tbl ,I.Name ,TblId ,I.index_id FROM (SELECT TblId = object_id(Tbl), Tbl FROM @Tables) O JOIN sys.indexes I ON I.object_id = TblId EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Insert',@Rows=@@rowcount INSERT INTO dbo.IndexProperties ( TableName, IndexName, PropertyName, PropertyValue ) SELECT Tbl, Ind, 'DATA_COMPRESSION', data_comp FROM (SELECT Tbl ,Ind ,data_comp = isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END FROM sys.partitions WHERE object_id = TblId AND index_id = IndId),'NONE') FROM @Indexes ) A WHERE NOT EXISTS (SELECT * FROM dbo.IndexProperties WHERE TableName = Tbl AND IndexName = Ind) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='IndexProperties',@Action='Insert',@Rows=@@rowcount DELETE FROM @Indexes WHERE Tbl IN ('Resource','ResourceCurrent','ResourceHistory') OR IndId = 1 EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Delete',@Rows=@@rowcount WHILE EXISTS (SELECT * FROM @Indexes) BEGIN SELECT TOP 1 @Tbl = Tbl, @Ind = Ind FROM @Indexes SET @Txt = 'ALTER INDEX '+@Ind+' ON dbo.'+@Tbl+' DISABLE' EXECUTE(@Txt) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target=@Ind,@Action='Disable',@Text=@Txt DELETE FROM @Indexes WHERE Tbl = @Tbl AND Ind = @Ind END EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; THROW END CATCH GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='DisableIndexes',@Action='Alter' GO IF object_id('dbo.ResourceCurrent') IS NULL BEGIN BEGIN TRY BEGIN TRANSACTION CREATE TABLE dbo.ResourceCurrent ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ,Version int NOT NULL ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceCurrent_RawResource_Length CHECK (RawResource > 0x0) ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL -- used for main CRUD operation CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceId UNIQUE (ResourceTypeId, ResourceId) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) ALTER TABLE dbo.ResourceCurrent SET ( LOCK_ESCALATION = AUTO ) CREATE UNIQUE INDEX IXU_ResourceTypeId_ResourceSurrogateId_WHERE_IsHistory_0_IsDeleted_0 ON dbo.ResourceCurrent (ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 AND IsDeleted = 0 ON PartitionScheme_ResourceTypeId (ResourceTypeId) CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceCurrent',@Action='Create' CREATE TABLE dbo.ResourceHistory ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ,Version int NOT NULL ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1, CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceHistory_RawResource_Length CHECK (RawResource > 0x0) ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL -- used for main CRUD operation ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) ALTER TABLE dbo.ResourceHistory SET ( LOCK_ESCALATION = AUTO ) CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceHistory',@Action='Create' COMMIT TRANSACTION END TRY BEGIN CATCH ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; THROW END CATCH END GO IF EXISTS (SELECT * FROM sys.objects WHERE object_id = object_id('dbo.Resource') AND type = 'u') AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'SkipHistorySeparation' AND Number = 1) BEGIN --CREATE TRIGGER dbo.ResourceIns EXECUTE(' CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource AFTER INSERT AS BEGIN INSERT INTO dbo.ResourceCurrent ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM Inserted WHERE IsHistory = 0 INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' --CREATE TRIGGER dbo.ResourceUpd EXECUTE(' CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource AFTER UPDATE AS BEGIN UPDATE B SET SearchParamHash = A.SearchParamHash -- this is the only update we support FROM Inserted A JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE A.IsHistory = 0 DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' --CREATE TRIGGER dbo.ResourceDel EXECUTE(' CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource AFTER DELETE AS BEGIN DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) DELETE FROM A FROM dbo.ResourceHistory A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' DECLARE @Types TABLE (ResourceTypeId smallint PRIMARY KEY, Name varchar(100)) DECLARE @MaxSurrogateId bigint = 0 ,@ResourceTypeId smallint IF NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') -- DELETE FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId' BEGIN DECLARE @MaxSurrogateIdTmp bigint INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes WHILE EXISTS (SELECT * FROM @Types) BEGIN SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types) SET @MaxSurrogateIdTmp = (SELECT max(ResourceSurrogateId) FROM Resource WHERE ResourceTypeId = @ResourceTypeId) IF @MaxSurrogateIdTmp > @MaxSurrogateId SET @MaxSurrogateId = @MaxSurrogateIdTmp DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId END INSERT INTO dbo.Parameters (Id, Bigint) SELECT 'HistorySeparation.MaxSurrogateId', @MaxSurrogateId END SET @MaxSurrogateId = (SELECT Bigint FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='@MaxSurrogateId',@Action='Select',@Text=@MaxSurrogateId -- Copy start ---------------------------------------------------------------------------------------------------------- DECLARE @Process varchar(100) = 'HistorySeparation.CopyResources' ,@Id varchar(100) = 'HistorySeparation.CopyResources.LastProcessed.TypeId.SurrogateId' ,@SurrogateId bigint ,@RowsToProcess int ,@ProcessedResources int ,@ReportDate datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 ,@Rows int ,@CurrentMaxSurrogateId bigint ,@LastProcessed varchar(100) ,@st datetime BEGIN TRY INSERT INTO dbo.Parameters (Id, Char) SELECT @Process, 'LogEvent' EXECUTE dbo.LogEvent @Process=@Process,@Status='Start' INSERT INTO dbo.Parameters (Id, Char) SELECT @Id, '0.0' WHERE NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = @Id) SET @LastProcessed = (SELECT Char FROM dbo.Parameters WHERE Id = @Id) INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Insert',@Rows=@@rowcount SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 1) SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 2) DELETE FROM @Types WHERE ResourceTypeId < @ResourceTypeId EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Delete',@Rows=@@rowcount WHILE EXISTS (SELECT * FROM @Types) -- Processing in ASC order BEGIN SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types ORDER BY ResourceTypeId) SET @ProcessedResources = 0 SET @CurrentMaxSurrogateId = 0 WHILE @CurrentMaxSurrogateId IS NOT NULL BEGIN BEGIN TRANSACTION SET @CurrentMaxSurrogateId = NULL SELECT @CurrentMaxSurrogateId = max(ResourceSurrogateId), @RowsToProcess = count(*) FROM (SELECT TOP 5000 ResourceSurrogateId -- 5000 is max to avoid lock escalation FROM dbo.Resource (HOLDLOCK) -- Hold locks for the duration of 2 inserts, so other write transactions cannot change data WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @MaxSurrogateId ORDER BY ResourceSurrogateId ) A IF @CurrentMaxSurrogateId IS NOT NULL BEGIN SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@CurrentMaxSurrogateId) SET @st = getUTCdate() INSERT INTO dbo.ResourceCurrent ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM (SELECT * FROM dbo.Resource A WITH (INDEX = 1) WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND IsHistory = 0 ) A WHERE NOT EXISTS (SELECT * FROM dbo.ResourceCurrent B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- surr id from $import insert can point in the past OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceCurrent',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st SET @st = getUTCdate() INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM (SELECT TOP (@DummyTop) * FROM dbo.Resource A WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND IsHistory = 1 ) A WHERE NOT EXISTS (SELECT * FROM dbo.ResourceHistory B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- history can be inserted by the new version insert in merge OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceHistory',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id COMMIT TRANSACTION SET @SurrogateId = @CurrentMaxSurrogateId SET @ProcessedResources += @RowsToProcess IF datediff(second, @ReportDate, getUTCdate()) > 60 BEGIN EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources SET @ReportDate = getUTCdate() SET @ProcessedResources = 0 END END ELSE BEGIN COMMIT TRANSACTION SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@MaxSurrogateId) UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id END END IF @ProcessedResources > 0 EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId SET @SurrogateId = 0 END EXECUTE dbo.LogEvent @Process=@Process,@Status='End' END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; THROW END CATCH -- Copy end ---------------------------------------------------------------------------------------------------------- DECLARE @OldRows bigint ,@CurrentRows bigint ,@HistoryRows bigint ,@msg varchar(1000) BEGIN TRY BEGIN TRANSACTION -- verification -- lock input SET @OldRows = (SELECT TOP 1 1 FROM dbo.Resource (TABLOCKX)) SET @OldRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('Resource') AND index_id IN (0,1)) EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='Resource',@Action='RowsCheck',@Text=@OldRows SET @CurrentRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceCurrent') AND index_id IN (0,1)) EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceCurrent',@Action='RowsCheck',@Text=@CurrentRows SET @HistoryRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceHistory') AND index_id IN (0,1)) EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceHistory',@Action='RowsCheck',@Text=@HistoryRows IF @CurrentRows + @HistoryRows <> @OldRows BEGIN SET @msg = 'OldRows='+convert(varchar,@OldRows)+' <> NewRows='+convert(varchar,@CurrentRows + @HistoryRows) RAISERROR(@msg,18,127) END COMMIT TRANSACTION -- verification EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Text='Completed' EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Started' SET lock_timeout 180000 -- 3 minutes BEGIN TRANSACTION -- table - view switch IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'KeepResourceTable' AND Number = 1) EXECUTE sp_rename 'Resource', 'Resource_Table' ELSE DROP TABLE dbo.Resource --CREATE VIEW dbo.Resource EXECUTE(' CREATE VIEW dbo.Resource AS SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsHistory ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM dbo.ResourceHistory UNION ALL SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsHistory ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,NULL FROM dbo.ResourceCurrent ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='Resource',@Action='Create' IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceIns' AND type = 'tr') DROP TRIGGER dbo.ResourceIns --CREATE TRIGGER dbo.ResourceIns EXECUTE(' CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT AS BEGIN INSERT INTO dbo.ResourceCurrent ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId FROM Inserted WHERE IsHistory = 0 INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceUpd' AND type = 'tr') DROP TRIGGER dbo.ResourceUpd --CREATE TRIGGER dbo.ResourceUpd EXECUTE(' CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE AS BEGIN IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) BEGIN UPDATE B SET SearchParamHash = A.SearchParamHash -- this is the only update we support FROM Inserted A JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE A.IsHistory = 0 RETURN END IF NOT UPDATE(IsHistory) RAISERROR(''Generic updates are not supported via Resource view'',18,127) DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) INSERT INTO dbo.ResourceHistory ( ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId ) SELECT ResourceTypeId ,ResourceSurrogateId ,ResourceId ,Version ,IsDeleted ,RequestMethod ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId ,HistoryTransactionId FROM Inserted WHERE IsHistory = 1 END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceDel' AND type = 'tr') DROP TRIGGER dbo.ResourceDel --CREATE TRIGGER dbo.ResourceDel EXECUTE(' CREATE TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE AS BEGIN DELETE FROM A FROM dbo.ResourceCurrent A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) DELETE FROM A FROM dbo.ResourceHistory A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) END ') EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' COMMIT TRANSACTION -- table - view switch EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Completed' END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; THROW END CATCH END GO EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='End' GO \ No newline at end of file +--SET TRANSACTION ISOLATION LEVEL READ COMMITTED -- Not sure that it matters, but to gurantee that SQL versioning is not used ---- Disable defrag --UPDATE Parameters SET Number = 0 WHERE Id = 'DefragWatchdog.IsEnabled' --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Update',@Rows=@@rowcount,@Text='disable defrag' --GO --IF (SELECT sum(reserved_page_count*8.0/1024/1024) FROM sys.dm_db_partition_stats) > 2500 -- skip for large databases --BEGIN -- INSERT INTO dbo.Parameters (Id, Number) SELECT 'SkipHistorySeparation', 1 -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Insert',@Rows=@@rowcount,@Text='SkipHistorySeparation' --END --GO --ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalStartId bigint = NULL, @GlobalEndId bigint = NULL --AS --set nocount on --DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' -- ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') -- +' S='+isnull(convert(varchar,@StartId),'NULL') -- +' E='+isnull(convert(varchar,@EndId),'NULL') -- +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') -- Could this just be a boolean for if historical records should be returned? GlobalEndId should equal EndId in all cases I can think of. -- ,@st datetime = getUTCdate() -- ,@DummyTop bigint = 9223372036854775807 --BEGIN TRY -- DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) -- DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) -- IF @GlobalEndId IS NOT NULL -- snapshot view -- BEGIN -- INSERT INTO @ResourceIds -- SELECT DISTINCT ResourceId -- FROM dbo.Resource -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId BETWEEN @StartId AND @EndId -- AND IsHistory = 1 -- AND IsDeleted = 0 -- OPTION (MAXDOP 1) -- IF @@rowcount > 0 -- INSERT INTO @SurrogateIds -- SELECT ResourceSurrogateId -- FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) -- FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) -- w/o hint access to Resource table is inefficient when many versions are present. Hint is ignored if Resource is a view. -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) -- AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId -- ) A -- WHERE RowId = 1 -- AND ResourceSurrogateId BETWEEN @StartId AND @EndId -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- END -- SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource -- FROM dbo.Resource -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId BETWEEN @StartId AND @EndId -- AND IsHistory = 0 -- AND IsDeleted = 0 -- UNION ALL -- SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource -- FROM @SurrogateIds -- JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId -- WHERE IsHistory = 1 -- AND IsDeleted = 0 -- OPTION (MAXDOP 1) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; -- THROW --END CATCH --GO --ALTER PROCEDURE dbo.DequeueJob @QueueType tinyint, @Worker varchar(100), @HeartbeatTimeoutSec int, @InputJobId bigint = NULL, @CheckTimeoutJobs bit = 0 --AS --set nocount on --DECLARE @SP varchar(100) = 'DequeueJob' -- ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') -- +' H='+isnull(convert(varchar,@HeartbeatTimeoutSec),'NULL') -- +' W='+isnull(@Worker,'NULL') -- +' IJ='+isnull(convert(varchar,@InputJobId),'NULL') -- +' T='+isnull(convert(varchar,@CheckTimeoutJobs),'NULL') -- ,@Rows int = 0 -- ,@st datetime = getUTCdate() -- ,@JobId bigint -- ,@msg varchar(100) -- ,@Lock varchar(100) -- ,@PartitionId tinyint -- ,@MaxPartitions tinyint = 16 -- !!! hardcoded -- ,@LookedAtPartitions tinyint = 0 --BEGIN TRY -- IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'DequeueJobStop' AND Number = 1) -- BEGIN -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=0,@Text='Skipped' -- RETURN -- END -- IF @InputJobId IS NULL -- SET @PartitionId = @MaxPartitions * rand() -- ELSE -- SET @PartitionId = @InputJobId % 16 -- SET TRANSACTION ISOLATION LEVEL READ COMMITTED -- WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions AND @CheckTimeoutJobs = 0 -- BEGIN -- SET @Lock = 'DequeueJob_'+convert(varchar,@QueueType)+'_'+convert(varchar,@PartitionId) -- BEGIN TRANSACTION -- EXECUTE sp_getapplock @Lock, 'Exclusive' -- UPDATE T -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = 1 -- running -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = T.JobId -- FROM dbo.JobQueue T WITH (PAGLOCK) -- JOIN (SELECT TOP 1 -- JobId -- FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) -- WHERE QueueType = @QueueType -- AND PartitionId = @PartitionId -- AND Status = 0 -- ORDER BY -- Priority -- ,JobId -- ) S -- ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId -- SET @Rows += @@rowcount -- COMMIT TRANSACTION -- IF @JobId IS NULL -- BEGIN -- SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END -- SET @LookedAtPartitions = @LookedAtPartitions + 1 -- END -- END -- -- Do timed out items. -- SET @LookedAtPartitions = 0 -- WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions -- BEGIN -- SET @Lock = 'DequeueStoreCopyWorkUnit_'+convert(varchar, @PartitionId) -- BEGIN TRANSACTION -- EXECUTE sp_getapplock @Lock, 'Exclusive' -- UPDATE T -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = CASE WHEN CancelRequested = 0 THEN 1 ELSE 4 END -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = CASE WHEN CancelRequested = 0 THEN T.JobId END -- ,Info = convert(varchar(1000),isnull(Info,'')+' Prev: Worker='+Worker+' Start='+convert(varchar,StartDate,121)) -- FROM dbo.JobQueue T WITH (PAGLOCK) -- JOIN (SELECT TOP 1 -- JobId -- FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) -- WHERE QueueType = @QueueType -- AND PartitionId = @PartitionId -- AND Status = 1 -- AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec -- ORDER BY -- Priority -- ,JobId -- ) S -- ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId -- SET @Rows += @@rowcount -- COMMIT TRANSACTION -- IF @JobId IS NULL -- BEGIN -- SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END -- SET @LookedAtPartitions = @LookedAtPartitions + 1 -- END -- END -- IF @InputJobId IS NOT NULL -- BEGIN -- UPDATE dbo.JobQueue WITH (PAGLOCK) -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = 1 -- running -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = JobId -- WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 0 AND JobId = @InputJobId -- SET @Rows += @@rowcount -- IF @JobId IS NULL -- BEGIN -- UPDATE dbo.JobQueue WITH (PAGLOCK) -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = 1 -- running -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = JobId -- WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 1 AND JobId = @InputJobId -- AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec -- SET @Rows += @@rowcount -- END -- END -- IF @JobId IS NOT NULL -- EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobId = @JobId -- SET @msg = 'J='+isnull(convert(varchar,@JobId),'NULL')+' P='+convert(varchar,@PartitionId) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows,@Text=@msg --END TRY --BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='DequeueJob',@Action='Alter' --GO --ALTER PROCEDURE dbo.GetActiveJobs @QueueType tinyint, @GroupId bigint = NULL --AS --set nocount on --DECLARE @SP varchar(100) = 'GetActiveJobs' -- ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') -- +' G='+isnull(convert(varchar,@GroupId),'NULL') -- ,@st datetime = getUTCdate() -- ,@JobIds BigintList -- ,@PartitionId tinyint -- ,@MaxPartitions tinyint = 16 -- !!! hardcoded -- ,@LookedAtPartitions tinyint = 0 -- ,@Rows int = 0 --BEGIN TRY -- SET @PartitionId = @MaxPartitions * rand() -- WHILE @LookedAtPartitions < @MaxPartitions -- BEGIN -- IF @GroupId IS NULL -- INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND Status IN (0,1) -- ELSE -- INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND GroupId = @GroupId AND Status IN (0,1) -- SET @Rows += @@rowcount -- SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END -- SET @LookedAtPartitions += 1 -- END -- IF @Rows > 0 -- EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='GetActiveJobs',@Action='Alter' --GO --INSERT INTO dbo.Parameters (Id, Char) SELECT 'HistorySeparation', 'LogEvent' --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Start' --GO --ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY --AS --set nocount on --DECLARE @st datetime = getUTCdate() -- ,@SP varchar(100) = 'GetResources' -- ,@InputRows int -- ,@DummyTop bigint = 9223372036854775807 -- ,@NotNullVersionExists bit -- ,@NullVersionExists bit -- ,@MinRT smallint -- ,@MaxRT smallint --SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys --DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) --BEGIN TRY -- IF @NotNullVersionExists = 1 -- IF @NullVersionExists = 0 -- SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- ELSE -- SELECT * -- FROM (SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version -- UNION ALL -- SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId -- WHERE IsHistory = 0 -- ) A -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- ELSE -- SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId -- WHERE IsHistory = 0 -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='GetResources',@Action='Alter' --GO --ALTER PROCEDURE dbo.MergeResources ---- This stored procedure can be used for: ---- 1. Ordinary put with single version per resource in input ---- 2. Put with history preservation (multiple input versions per resource) ---- 3. Copy from one gen2 store to another with ResourceSurrogateId preserved. -- @AffectedRows int = 0 OUT -- ,@RaiseExceptionOnConflict bit = 1 -- ,@IsResourceChangeCaptureEnabled bit = 0 -- ,@TransactionId bigint = NULL -- ,@SingleTransaction bit = 1 -- ,@Resources dbo.ResourceList READONLY -- ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY -- ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY -- ,@TokenSearchParams dbo.TokenSearchParamList READONLY -- ,@TokenTexts dbo.TokenTextList READONLY -- ,@StringSearchParams dbo.StringSearchParamList READONLY -- ,@UriSearchParams dbo.UriSearchParamList READONLY -- ,@NumberSearchParams dbo.NumberSearchParamList READONLY -- ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY -- ,@DateTimeSearchParms dbo.DateTimeSearchParamList READONLY -- ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY -- ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY -- ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY -- ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY -- ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY -- ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY --AS --set nocount on --DECLARE @st datetime = getUTCdate() -- ,@SP varchar(100) = object_name(@@procid) -- ,@DummyTop bigint = 9223372036854775807 -- ,@InitialTranCount int = @@trancount -- ,@IsRetry bit = 0 --DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') --SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') --SET @AffectedRows = 0 --BEGIN TRY -- DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) -- DECLARE @ResourceInfos AS TABLE -- ( -- ResourceTypeId smallint NOT NULL -- ,SurrogateId bigint NOT NULL -- ,Version int NOT NULL -- ,KeepHistory bit NOT NULL -- ,PreviousVersion int NULL -- ,PreviousSurrogateId bigint NULL -- PRIMARY KEY (ResourceTypeId, SurrogateId) -- ) -- DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) -- IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 -- SET @SingleTransaction = 1 -- SET @Mode += ' ST='+convert(varchar,@SingleTransaction) -- -- perform retry check in transaction to hold locks -- IF @InitialTranCount = 0 -- BEGIN -- IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them -- FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE B.IsHistory = 0 -- ) -- BEGIN -- BEGIN TRANSACTION -- INSERT INTO @Existing -- ( ResourceTypeId, SurrogateId ) -- SELECT B.ResourceTypeId, B.ResourceSurrogateId -- FROM (SELECT TOP (@DummyTop) * FROM @Resources) A -- JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE B.IsHistory = 0 -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- IF @@rowcount > 0 SET @IsRetry = 1 -- IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction -- END -- END -- SET @Mode += ' R='+convert(varchar,@IsRetry) -- IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION -- IF @IsRetry = 0 -- BEGIN -- INSERT INTO @ResourceInfos -- ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) -- SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId -- FROM (SELECT TOP (@DummyTop) * FROM @Resources WHERE HasVersionToCompare = 1) A -- LEFT OUTER JOIN dbo.Resource B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. -- ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <> PreviousVersion + 1) -- THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 -- INSERT INTO @PreviousSurrogateIds -- SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory -- FROM @ResourceInfos -- WHERE PreviousSurrogateId IS NOT NULL -- IF @@rowcount > 0 -- BEGIN -- UPDATE dbo.Resource -- SET IsHistory = 1 -- WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) -- SET @AffectedRows += @@rowcount -- IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) -- UPDATE dbo.Resource -- SET IsHistory = 1 -- ,RawResource = 0xF -- "invisible" value -- ,SearchParamHash = NULL -- ,HistoryTransactionId = @TransactionId -- WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) -- ELSE -- DELETE FROM dbo.Resource WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenText WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.StringSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.UriSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.NumberSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.QuantitySearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.DateTimeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.ReferenceTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenDateTimeCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenQuantityCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenStringCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' -- END -- INSERT INTO dbo.Resource -- ( ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId ) -- SELECT ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId -- FROM @Resources -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ResourceWriteClaim -- ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) -- SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue -- FROM @ResourceWriteClaims -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion -- FROM @ReferenceSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow -- FROM @TokenSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenText -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text -- FROM @TokenTexts -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.StringSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax -- FROM @StringSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.UriSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri -- FROM @UriSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.NumberSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue -- FROM @NumberSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.QuantitySearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue -- FROM @QuantitySearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.DateTimeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax -- FROM @DateTimeSearchParms -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 -- FROM @ReferenceTokenCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 -- FROM @TokenTokenCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenDateTimeCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 -- FROM @TokenDateTimeCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenQuantityCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 -- FROM @TokenQuantityCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenStringCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 -- FROM @TokenStringCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenNumberNumberCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange -- FROM @TokenNumberNumberCompositeSearchParams -- SET @AffectedRows += @@rowcount -- END -- @IsRetry = 0 -- ELSE -- BEGIN -- @IsRetry = 1 -- INSERT INTO dbo.ResourceWriteClaim -- ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) -- SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceWriteClaims) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.ResourceWriteClaim C WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion -- FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow -- FROM (SELECT TOP (@DummyTop) * FROM @TokenSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenText -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text -- FROM (SELECT TOP (@DummyTop) * FROM @TokenTexts) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.StringSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax -- FROM (SELECT TOP (@DummyTop) * FROM @StringSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenText C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.UriSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri -- FROM (SELECT TOP (@DummyTop) * FROM @UriSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.UriSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.NumberSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue -- FROM (SELECT TOP (@DummyTop) * FROM @NumberSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.NumberSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.QuantitySearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue -- FROM (SELECT TOP (@DummyTop) * FROM @QuantitySearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.QuantitySearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.DateTimeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax -- FROM (SELECT TOP (@DummyTop) * FROM @DateTimeSearchParms) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 -- FROM (SELECT TOP (@DummyTop) * FROM @ReferenceTokenCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.DateTimeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenTokenCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenTokenCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenDateTimeCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenDateTimeCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenDateTimeCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenQuantityCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenQuantityCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenQuantityCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenStringCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenStringCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenStringCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenNumberNumberCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange -- FROM (SELECT TOP (@DummyTop) * FROM @TokenNumberNumberCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenNumberNumberCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- END -- IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. -- EXECUTE dbo.CaptureResourceIdsForChanges @Resources -- IF @TransactionId IS NOT NULL -- EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId -- IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows --END TRY --BEGIN CATCH -- IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource''%' OR error_message() LIKE '%''dbo.ResourceCurrent''%' OR error_message() LIKE '%''dbo.ResourceHistory''%') -- handles old and separated tables -- THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; -- ELSE -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='MergeResources',@Action='Alter' --GO --ALTER PROCEDURE dbo.UpdateResourceSearchParams -- @FailedResources int = 0 OUT -- ,@Resources dbo.ResourceList READONLY -- ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY -- ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY -- ,@TokenSearchParams dbo.TokenSearchParamList READONLY -- ,@TokenTexts dbo.TokenTextList READONLY -- ,@StringSearchParams dbo.StringSearchParamList READONLY -- ,@UriSearchParams dbo.UriSearchParamList READONLY -- ,@NumberSearchParams dbo.NumberSearchParamList READONLY -- ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY -- ,@DateTimeSearchParams dbo.DateTimeSearchParamList READONLY -- ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY -- ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY -- ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY -- ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY -- ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY -- ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY --AS --set nocount on --DECLARE @st datetime = getUTCdate() -- ,@SP varchar(100) = object_name(@@procid) -- ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') -- ,@Rows int --BEGIN TRY -- DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) -- BEGIN TRANSACTION -- -- Update the search parameter hash value in the main resource table -- -- Avoid join to enable update via view -- UPDATE A -- SET SearchParamHash = (SELECT SearchParamHash FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- FROM dbo.Resource A -- WHERE IsHistory = 0 -- AND EXISTS (SELECT * FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- SET @Rows = @@rowcount -- -- First, delete all the search params of the resources to reindex. -- DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.ReferenceSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- -- Next, insert all the new search params. -- INSERT INTO dbo.ResourceWriteClaim -- ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) -- SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue -- FROM @ResourceWriteClaims -- INSERT INTO dbo.ReferenceSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion -- FROM @ReferenceSearchParams -- INSERT INTO dbo.TokenSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow -- FROM @TokenSearchParams -- INSERT INTO dbo.TokenText -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text -- FROM @TokenTexts -- INSERT INTO dbo.StringSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax -- FROM @StringSearchParams -- INSERT INTO dbo.UriSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri -- FROM @UriSearchParams -- INSERT INTO dbo.NumberSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue -- FROM @NumberSearchParams -- INSERT INTO dbo.QuantitySearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue -- FROM @QuantitySearchParams -- INSERT INTO dbo.DateTimeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax -- FROM @DateTimeSearchParams -- INSERT INTO dbo.ReferenceTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 -- FROM @ReferenceTokenCompositeSearchParams -- INSERT INTO dbo.TokenTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 -- FROM @TokenTokenCompositeSearchParams -- INSERT INTO dbo.TokenDateTimeCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 -- FROM @TokenDateTimeCompositeSearchParams -- INSERT INTO dbo.TokenQuantityCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 -- FROM @TokenQuantityCompositeSearchParams -- INSERT INTO dbo.TokenStringCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 -- FROM @TokenStringCompositeSearchParams -- INSERT INTO dbo.TokenNumberNumberCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange -- FROM @TokenNumberNumberCompositeSearchParams -- COMMIT TRANSACTION -- SET @FailedResources = (SELECT count(*) FROM @Resources) - @Rows -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows --END TRY --BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='UpdateResourceSearchParams',@Action='Alter' --GO --ALTER PROCEDURE dbo.DisableIndexes --WITH EXECUTE AS 'dbo' --AS --set nocount on --DECLARE @SP varchar(100) = 'DisableIndexes' -- ,@Mode varchar(200) = '' -- ,@st datetime = getUTCdate() -- ,@Tbl varchar(100) -- ,@Ind varchar(200) -- ,@Txt varchar(4000) --BEGIN TRY -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start' -- DECLARE @Tables TABLE (Tbl varchar(100) PRIMARY KEY, Supported bit) -- INSERT INTO @Tables EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0 -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Tables',@Action='Insert',@Rows=@@rowcount -- DECLARE @Indexes TABLE (Tbl varchar(100), Ind varchar(200), TblId int, IndId int PRIMARY KEY (Tbl, Ind)) -- INSERT INTO @Indexes -- SELECT Tbl -- ,I.Name -- ,TblId -- ,I.index_id -- FROM (SELECT TblId = object_id(Tbl), Tbl FROM @Tables) O -- JOIN sys.indexes I ON I.object_id = TblId -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Insert',@Rows=@@rowcount -- INSERT INTO dbo.IndexProperties -- ( TableName, IndexName, PropertyName, PropertyValue ) -- SELECT Tbl, Ind, 'DATA_COMPRESSION', data_comp -- FROM (SELECT Tbl -- ,Ind -- ,data_comp = isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END FROM sys.partitions WHERE object_id = TblId AND index_id = IndId),'NONE') -- FROM @Indexes -- ) A -- WHERE NOT EXISTS (SELECT * FROM dbo.IndexProperties WHERE TableName = Tbl AND IndexName = Ind) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='IndexProperties',@Action='Insert',@Rows=@@rowcount -- DELETE FROM @Indexes WHERE Tbl IN ('Resource','ResourceCurrent','ResourceHistory') OR IndId = 1 -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Delete',@Rows=@@rowcount -- WHILE EXISTS (SELECT * FROM @Indexes) -- BEGIN -- SELECT TOP 1 @Tbl = Tbl, @Ind = Ind FROM @Indexes -- SET @Txt = 'ALTER INDEX '+@Ind+' ON dbo.'+@Tbl+' DISABLE' -- EXECUTE(@Txt) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target=@Ind,@Action='Disable',@Text=@Txt -- DELETE FROM @Indexes WHERE Tbl = @Tbl AND Ind = @Ind -- END -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='DisableIndexes',@Action='Alter' --GO --IF object_id('dbo.ResourceCurrent') IS NULL --BEGIN -- BEGIN TRY -- BEGIN TRANSACTION -- CREATE TABLE dbo.ResourceCurrent -- ( -- ResourceTypeId smallint NOT NULL -- ,ResourceSurrogateId bigint NOT NULL -- ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL -- ,Version int NOT NULL -- ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) -- ,IsDeleted bit NOT NULL -- ,RequestMethod varchar(10) NULL -- ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceCurrent_RawResource_Length CHECK (RawResource > 0x0) -- ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 -- ,SearchParamHash varchar(64) NULL -- ,TransactionId bigint NULL -- used for main CRUD operation -- CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ,CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceId UNIQUE (ResourceTypeId, ResourceId) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ) -- ALTER TABLE dbo.ResourceCurrent SET ( LOCK_ESCALATION = AUTO ) -- CREATE UNIQUE INDEX IXU_ResourceTypeId_ResourceSurrogateId_WHERE_IsHistory_0_IsDeleted_0 ON dbo.ResourceCurrent (ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 AND IsDeleted = 0 ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceCurrent',@Action='Create' -- CREATE TABLE dbo.ResourceHistory -- ( -- ResourceTypeId smallint NOT NULL -- ,ResourceSurrogateId bigint NOT NULL -- ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL -- ,Version int NOT NULL -- ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1, CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1) -- ,IsDeleted bit NOT NULL -- ,RequestMethod varchar(10) NULL -- ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceHistory_RawResource_Length CHECK (RawResource > 0x0) -- ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 -- ,SearchParamHash varchar(64) NULL -- ,TransactionId bigint NULL -- used for main CRUD operation -- ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state -- CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ,CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ) -- ALTER TABLE dbo.ResourceHistory SET ( LOCK_ESCALATION = AUTO ) -- CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceHistory',@Action='Create' -- COMMIT TRANSACTION -- END TRY -- BEGIN CATCH -- ROLLBACK TRANSACTION -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; -- THROW -- END CATCH --END --GO --IF EXISTS (SELECT * FROM sys.objects WHERE object_id = object_id('dbo.Resource') AND type = 'u') -- AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'SkipHistorySeparation' AND Number = 1) --BEGIN -- --CREATE TRIGGER dbo.ResourceIns -- EXECUTE(' --CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource AFTER INSERT --AS --BEGIN -- INSERT INTO dbo.ResourceCurrent -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM Inserted -- WHERE IsHistory = 0 -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' -- --CREATE TRIGGER dbo.ResourceUpd -- EXECUTE(' --CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource AFTER UPDATE --AS --BEGIN -- UPDATE B -- SET SearchParamHash = A.SearchParamHash -- this is the only update we support -- FROM Inserted A -- JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE A.IsHistory = 0 -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' -- --CREATE TRIGGER dbo.ResourceDel -- EXECUTE(' --CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource AFTER DELETE --AS --BEGIN -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) -- DELETE FROM A -- FROM dbo.ResourceHistory A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' -- DECLARE @Types TABLE (ResourceTypeId smallint PRIMARY KEY, Name varchar(100)) -- DECLARE @MaxSurrogateId bigint = 0 -- ,@ResourceTypeId smallint -- IF NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') -- DELETE FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId' -- BEGIN -- DECLARE @MaxSurrogateIdTmp bigint -- INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes -- WHILE EXISTS (SELECT * FROM @Types) -- BEGIN -- SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types) -- SET @MaxSurrogateIdTmp = (SELECT max(ResourceSurrogateId) FROM Resource WHERE ResourceTypeId = @ResourceTypeId) -- IF @MaxSurrogateIdTmp > @MaxSurrogateId SET @MaxSurrogateId = @MaxSurrogateIdTmp -- DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId -- END -- INSERT INTO dbo.Parameters (Id, Bigint) SELECT 'HistorySeparation.MaxSurrogateId', @MaxSurrogateId -- END -- SET @MaxSurrogateId = (SELECT Bigint FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='@MaxSurrogateId',@Action='Select',@Text=@MaxSurrogateId -- -- Copy start ---------------------------------------------------------------------------------------------------------- -- DECLARE @Process varchar(100) = 'HistorySeparation.CopyResources' -- ,@Id varchar(100) = 'HistorySeparation.CopyResources.LastProcessed.TypeId.SurrogateId' -- ,@SurrogateId bigint -- ,@RowsToProcess int -- ,@ProcessedResources int -- ,@ReportDate datetime = getUTCdate() -- ,@DummyTop bigint = 9223372036854775807 -- ,@Rows int -- ,@CurrentMaxSurrogateId bigint -- ,@LastProcessed varchar(100) -- ,@st datetime -- BEGIN TRY -- INSERT INTO dbo.Parameters (Id, Char) SELECT @Process, 'LogEvent' -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Start' -- INSERT INTO dbo.Parameters (Id, Char) SELECT @Id, '0.0' WHERE NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = @Id) -- SET @LastProcessed = (SELECT Char FROM dbo.Parameters WHERE Id = @Id) -- INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Insert',@Rows=@@rowcount -- SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 1) -- SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 2) -- DELETE FROM @Types WHERE ResourceTypeId < @ResourceTypeId -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Delete',@Rows=@@rowcount -- WHILE EXISTS (SELECT * FROM @Types) -- Processing in ASC order -- BEGIN -- SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types ORDER BY ResourceTypeId) -- SET @ProcessedResources = 0 -- SET @CurrentMaxSurrogateId = 0 -- WHILE @CurrentMaxSurrogateId IS NOT NULL -- BEGIN -- BEGIN TRANSACTION -- SET @CurrentMaxSurrogateId = NULL -- SELECT @CurrentMaxSurrogateId = max(ResourceSurrogateId), @RowsToProcess = count(*) -- FROM (SELECT TOP 5000 ResourceSurrogateId -- 5000 is max to avoid lock escalation -- FROM dbo.Resource (HOLDLOCK) -- Hold locks for the duration of 2 inserts, so other write transactions cannot change data -- WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @MaxSurrogateId -- ORDER BY ResourceSurrogateId -- ) A -- IF @CurrentMaxSurrogateId IS NOT NULL -- BEGIN -- SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@CurrentMaxSurrogateId) -- SET @st = getUTCdate() -- INSERT INTO dbo.ResourceCurrent -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM (SELECT * -- FROM dbo.Resource A WITH (INDEX = 1) -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId > @SurrogateId -- AND ResourceSurrogateId <= @CurrentMaxSurrogateId -- AND IsHistory = 0 -- ) A -- WHERE NOT EXISTS (SELECT * FROM dbo.ResourceCurrent B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- surr id from $import insert can point in the past -- OPTION (MAXDOP 1) -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceCurrent',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st -- SET @st = getUTCdate() -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM (SELECT TOP (@DummyTop) * -- FROM dbo.Resource A -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId > @SurrogateId -- AND ResourceSurrogateId <= @CurrentMaxSurrogateId -- AND IsHistory = 1 -- ) A -- WHERE NOT EXISTS (SELECT * FROM dbo.ResourceHistory B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- history can be inserted by the new version insert in merge -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceHistory',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st -- UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id -- COMMIT TRANSACTION -- SET @SurrogateId = @CurrentMaxSurrogateId -- SET @ProcessedResources += @RowsToProcess -- IF datediff(second, @ReportDate, getUTCdate()) > 60 -- BEGIN -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources -- SET @ReportDate = getUTCdate() -- SET @ProcessedResources = 0 -- END -- END -- ELSE -- BEGIN -- COMMIT TRANSACTION -- SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@MaxSurrogateId) -- UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id -- END -- END -- IF @ProcessedResources > 0 -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources -- DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId -- SET @SurrogateId = 0 -- END -- EXECUTE dbo.LogEvent @Process=@Process,@Status='End' -- END TRY -- BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; -- THROW -- END CATCH -- -- Copy end ---------------------------------------------------------------------------------------------------------- -- DECLARE @OldRows bigint -- ,@CurrentRows bigint -- ,@HistoryRows bigint -- ,@msg varchar(1000) -- BEGIN TRY -- BEGIN TRANSACTION -- verification -- -- lock input -- SET @OldRows = (SELECT TOP 1 1 FROM dbo.Resource (TABLOCKX)) -- SET @OldRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('Resource') AND index_id IN (0,1)) -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='Resource',@Action='RowsCheck',@Text=@OldRows -- SET @CurrentRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceCurrent') AND index_id IN (0,1)) -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceCurrent',@Action='RowsCheck',@Text=@CurrentRows -- SET @HistoryRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceHistory') AND index_id IN (0,1)) -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceHistory',@Action='RowsCheck',@Text=@HistoryRows -- IF @CurrentRows + @HistoryRows <> @OldRows -- BEGIN -- SET @msg = 'OldRows='+convert(varchar,@OldRows)+' <> NewRows='+convert(varchar,@CurrentRows + @HistoryRows) -- RAISERROR(@msg,18,127) -- END -- COMMIT TRANSACTION -- verification -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Text='Completed' -- EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Started' -- SET lock_timeout 180000 -- 3 minutes -- BEGIN TRANSACTION -- table - view switch -- IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'KeepResourceTable' AND Number = 1) -- EXECUTE sp_rename 'Resource', 'Resource_Table' -- ELSE -- DROP TABLE dbo.Resource -- --CREATE VIEW dbo.Resource -- EXECUTE(' --CREATE VIEW dbo.Resource --AS --SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsHistory -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM dbo.ResourceHistory --UNION ALL --SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsHistory -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,NULL -- FROM dbo.ResourceCurrent -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='Resource',@Action='Create' -- IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceIns' AND type = 'tr') -- DROP TRIGGER dbo.ResourceIns -- --CREATE TRIGGER dbo.ResourceIns -- EXECUTE(' --CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT --AS --BEGIN -- INSERT INTO dbo.ResourceCurrent -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM Inserted -- WHERE IsHistory = 0 -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' -- IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceUpd' AND type = 'tr') -- DROP TRIGGER dbo.ResourceUpd -- --CREATE TRIGGER dbo.ResourceUpd -- EXECUTE(' --CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE --AS --BEGIN -- IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) -- BEGIN -- UPDATE B -- SET SearchParamHash = A.SearchParamHash -- this is the only update we support -- FROM Inserted A -- JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE A.IsHistory = 0 -- RETURN -- END -- IF NOT UPDATE(IsHistory) -- RAISERROR(''Generic updates are not supported via Resource view'',18,127) -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' -- IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceDel' AND type = 'tr') -- DROP TRIGGER dbo.ResourceDel -- --CREATE TRIGGER dbo.ResourceDel -- EXECUTE(' --CREATE TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE --AS --BEGIN -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) -- DELETE FROM A -- FROM dbo.ResourceHistory A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' -- COMMIT TRANSACTION -- table - view switch -- EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Completed' -- END TRY -- BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; -- THROW -- END CATCH --END --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='End' --GO \ No newline at end of file From 7060321dc1cc1f214614078c97497471586eca99 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 22 Oct 2024 13:40:19 -0700 Subject: [PATCH 013/111] set end date on enqueue --- .../Features/Schema/Migrations/84.sql | 5 +++-- .../Features/Schema/Sql/Sprocs/EnqueueJobs.sql | 2 ++ 2 files changed, 5 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 679de75ca4..f0829b1f87 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -2240,7 +2240,7 @@ BEGIN TRY FROM dbo.JobQueue WHERE QueueType = @QueueType ORDER BY JobId DESC), 0); - INSERT INTO dbo.JobQueue (QueueType, GroupId, JobId, Definition, DefinitionHash, Status, Result, StartDate) + INSERT INTO dbo.JobQueue (QueueType, GroupId, JobId, Definition, DefinitionHash, Status, Result, StartDate, EndDate) OUTPUT inserted.JobId INTO @JobIds SELECT @QueueType, isnull(@GroupId, @MaxJobId + 1) AS GroupId, @@ -2249,7 +2249,8 @@ BEGIN TRY DefinitionHash, isnull(@Status, 0) AS Status, CASE WHEN @Status = 2 THEN @Result ELSE NULL END AS Result, - CASE WHEN @Status = 1 THEN getUTCdate() ELSE @StartDate END AS StartDate + CASE WHEN @Status = 1 THEN getUTCdate() ELSE @StartDate END AS StartDate, + CASE WHEN @Status = 2 THEN getUTCdate() ELSE NULL END AS EndDate FROM (SELECT @MaxJobId + row_number() OVER (ORDER BY Dummy) AS JobId, * FROM (SELECT *, diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/EnqueueJobs.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/EnqueueJobs.sql index 27cc56f692..5e0e2fb7db 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/EnqueueJobs.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/EnqueueJobs.sql @@ -49,6 +49,7 @@ BEGIN TRY ,Status ,Result ,StartDate + ,EndDate ) OUTPUT inserted.JobId INTO @JobIds SELECT @QueueType @@ -59,6 +60,7 @@ BEGIN TRY ,Status = isnull(@Status,0) ,Result = CASE WHEN @Status = 2 THEN @Result ELSE NULL END ,StartDate = CASE WHEN @Status = 1 THEN getUTCdate() ELSE @StartDate END + ,EndDate = CASE WHEN @Status = 2 THEN getUTCdate() ELSE NULL END FROM (SELECT JobId = @MaxJobId + row_number() OVER (ORDER BY Dummy), * FROM (SELECT *, Dummy = 0 FROM @Input) A) A -- preserve input order WHERE NOT EXISTS (SELECT * FROM dbo.JobQueue B WITH (INDEX = IX_QueueType_DefinitionHash) WHERE B.QueueType = @QueueType AND B.DefinitionHash = A.DefinitionHash AND B.Status <> 5) SET @Rows = @@rowcount From 427cdfa4fdffbb58a567b18b9cc6225999c80a7b Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 22 Oct 2024 13:50:10 -0700 Subject: [PATCH 014/111] rename secondary to adls --- .../Storage/{SqlSecondaryStore.cs => SqlAdlsStore.cs} | 6 +++--- .../Features/Storage/SqlServerFhirDataStore.cs | 6 +++--- .../Features/Storage/SqlStoreClient.cs | 6 +++--- 3 files changed, 9 insertions(+), 9 deletions(-) rename src/Microsoft.Health.Fhir.SqlServer/Features/Storage/{SqlSecondaryStore.cs => SqlAdlsStore.cs} (96%) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlSecondaryStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsStore.cs similarity index 96% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlSecondaryStore.cs rename to src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsStore.cs index 3fd090a320..3987e3a43a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlSecondaryStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsStore.cs @@ -13,7 +13,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Storage { - internal class SqlSecondaryStore + internal class SqlAdlsStore { private static readonly object _parameterLocker = new object(); private static string _adlsContainer; @@ -25,7 +25,7 @@ internal class SqlSecondaryStore private static BlobContainerClient _adlsClient; private static bool _adlsIsSet; - public SqlSecondaryStore(ISqlRetryService sqlRetryService, ILogger logger) + public SqlAdlsStore(ISqlRetryService sqlRetryService, ILogger logger) { EnsureArg.IsNotNull(sqlRetryService, nameof(sqlRetryService)); @@ -72,7 +72,7 @@ public SqlSecondaryStore(ISqlRetryService sqlRetryService, ILogger logger) public static string AdlsAccountKey => _adlsIsSet ? _adlsAccountKey : throw new ArgumentOutOfRangeException(); - private static string GetStorageParameter(ISqlRetryService sqlRetryService, ILogger logger, string parameterId) + private static string GetStorageParameter(ISqlRetryService sqlRetryService, ILogger logger, string parameterId) { lock (_parameterLocker) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index e5e2c6d007..a91d88b0db 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -123,7 +123,7 @@ public SqlServerFhirDataStore( } } - _ = new SqlSecondaryStore(_sqlRetryService, _logger); + _ = new SqlAdlsStore(_sqlRetryService, _logger); } internal SqlStoreClient StoreClient => _sqlStoreClient; @@ -139,7 +139,7 @@ private async Task PutRawResourcesIntoAdls(IReadOnlyList r retry: try { - using var stream = await SqlSecondaryStore.AdlsClient.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); + using var stream = await SqlAdlsStore.AdlsClient.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); using var writer = new StreamWriter(stream); var offset = 0; foreach (var resource in resources) @@ -761,7 +761,7 @@ internal async Task MergeResourcesWrapperAsync(long transactionId, bool singleTr cmd.Parameters.AddWithValue("@IsResourceChangeCaptureEnabled", _coreFeatures.SupportsResourceChangeCapture); cmd.Parameters.AddWithValue("@TransactionId", transactionId); cmd.Parameters.AddWithValue("@SingleTransaction", singleTransaction); - if (SqlSecondaryStore.AdlsClient != null) + if (SqlAdlsStore.AdlsClient != null) { await PutRawResourcesIntoAdls(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 0c1b9bd826..5357d0e7e2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -77,7 +77,7 @@ public async Task> GetAsync(IReadOnlyList { return ReadResourceWrapper(reader, false, decompress, SqlSecondaryStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, false, decompress, SqlAdlsStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); } catch (Exception e) { @@ -99,7 +99,7 @@ public static Lazy GetRawResourceFromAdls(long transactionId, int offset return new Lazy(() => { var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(transactionId); - using var reader = new StreamReader(SqlSecondaryStore.AdlsClient.GetBlobClient(blobName).OpenRead(offsetInFile)); + using var reader = new StreamReader(SqlAdlsStore.AdlsClient.GetBlobClient(blobName).OpenRead(offsetInFile)); var line = reader.ReadLine(); return line; }); @@ -168,7 +168,7 @@ internal async Task> GetResourcesByTransactionIdA await using var cmd = new SqlCommand() { CommandText = "dbo.GetResourcesByTransactionId", CommandType = CommandType.StoredProcedure, CommandTimeout = 600 }; cmd.Parameters.AddWithValue("@TransactionId", transactionId); //// ignore invisible resources - return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlSecondaryStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlAdlsStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); } private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func decompress, BlobContainerClient adlsClient, Func getResourceTypeName) From 02a545fa46fd33fe9789f129da52f15a86df665f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 27 Oct 2024 15:46:49 -0700 Subject: [PATCH 015/111] defrag formatting --- .../Features/Schema/Sql/Sprocs/Defrag.sql | 13 ++++++------- 1 file changed, 6 insertions(+), 7 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/Defrag.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/Defrag.sql index 4021bbceb8..0d92a54fce 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/Defrag.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/Defrag.sql @@ -20,13 +20,12 @@ BEGIN TRY SET @IndexId = (SELECT index_id FROM sys.indexes WHERE object_id = object_id(@TableName) AND name = @IndexName) SET @Sql = 'ALTER INDEX '+quotename(@IndexName)+' ON dbo.'+quotename(@TableName)+' '+@Operation + CASE WHEN @IsPartitioned = 1 THEN ' PARTITION = '+convert(varchar,@PartitionNumber) ELSE '' END - + CASE WHEN @Operation = 'REBUILD' THEN ' WITH (ONLINE = ON ' - + CASE - WHEN EXISTS (SELECT * FROM sys.partitions WHERE object_id = object_id(@TableName) AND index_id = @IndexId AND data_compression_desc = 'PAGE') - THEN ', DATA_COMPRESSION = PAGE' - ELSE ')' - END - ELSE '' + + CASE + WHEN @Operation = 'REBUILD' + THEN ' WITH (ONLINE = ON' + + CASE WHEN EXISTS (SELECT * FROM sys.partitions WHERE object_id = object_id(@TableName) AND index_id = @IndexId AND data_compression_desc = 'PAGE') THEN ', DATA_COMPRESSION = PAGE' ELSE '' END + + ')' + ELSE '' END EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start',@Text=@Sql From fbbaf207fbfaeb087da791ea3c0f7e26915c9a42 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 28 Oct 2024 10:22:06 -0700 Subject: [PATCH 016/111] set timeout to 0 for getting frag --- .../Features/Watchdogs/DefragWatchdog.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/DefragWatchdog.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/DefragWatchdog.cs index b69729c5eb..6400814f65 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/DefragWatchdog.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/DefragWatchdog.cs @@ -180,7 +180,7 @@ private async Task> GetExistingItems(long groupId, C private async Task> GetFragmentation(string tableName, string indexName, int? partitionNumber, CancellationToken cancellationToken) { - await using var cmd = new SqlCommand("dbo.DefragGetFragmentation") { CommandType = CommandType.StoredProcedure }; + await using var cmd = new SqlCommand("dbo.DefragGetFragmentation") { CommandType = CommandType.StoredProcedure, CommandTimeout = 0 }; // this is long running cmd.Parameters.AddWithValue("@TableName", tableName); if (indexName != null) { From 3f5dcd9de3f9da3734958b23e82931225025513e Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 28 Oct 2024 12:52:19 -0700 Subject: [PATCH 017/111] isnull on input param --- .../Features/Schema/Sql/Sprocs/DefragGetFragmentation.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DefragGetFragmentation.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DefragGetFragmentation.sql index c0e4cd3d5e..e72f27abdf 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DefragGetFragmentation.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DefragGetFragmentation.sql @@ -13,7 +13,7 @@ DECLARE @SP varchar(100) = object_name(@@procid) ,@PreviousGroupId bigint ,@IndexId int -DECLARE @Mode varchar(200) = 'T='+@TableName+' I='+isnull(@IndexName,'NULL')+' P='+convert(varchar,@PartitionNumber)+' MF='+convert(varchar,@MinFragPct)+' MS='+convert(varchar,@MinSizeGB) +DECLARE @Mode varchar(200) = 'T='+@TableName+' I='+isnull(@IndexName,'NULL')+' P='+isnull(convert(varchar,@PartitionNumber),'NULL')+' MF='+convert(varchar,@MinFragPct)+' MS='+convert(varchar,@MinSizeGB) BEGIN TRY EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start' From 5569ea1a5de8481d8001d79e71b3241a136f78a7 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 29 Oct 2024 18:39:35 -0700 Subject: [PATCH 018/111] after merge from main --- .../Features/Schema/Migrations/84.sql | 18 ++++++++++-------- 1 file changed, 10 insertions(+), 8 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index f0829b1f87..0ef42106a9 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -1651,16 +1651,17 @@ BEGIN TRY FROM sys.indexes WHERE object_id = object_id(@TableName) AND name = @IndexName); - SET @Sql = 'ALTER INDEX ' + quotename(@IndexName) + ' ON dbo.' + quotename(@TableName) + ' ' + @Operation + CASE WHEN @IsPartitioned = 1 THEN ' PARTITION = ' + CONVERT (VARCHAR, @PartitionNumber) ELSE '' END + CASE WHEN @Operation = 'REBUILD' THEN ' WITH (ONLINE = ON ' + CASE WHEN EXISTS (SELECT * - FROM sys.partitions - WHERE object_id = object_id(@TableName) - AND index_id = @IndexId - AND data_compression_desc = 'PAGE') THEN ', DATA_COMPRESSION = PAGE' ELSE ')' END ELSE '' END; + SET @Sql = 'ALTER INDEX ' + quotename(@IndexName) + ' ON dbo.' + quotename(@TableName) + ' ' + @Operation + CASE WHEN @IsPartitioned = 1 THEN ' PARTITION = ' + CONVERT (VARCHAR, @PartitionNumber) ELSE '' END + CASE WHEN @Operation = 'REBUILD' THEN ' WITH (ONLINE = ON' + CASE WHEN EXISTS (SELECT * + FROM sys.partitions + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId + AND data_compression_desc = 'PAGE') THEN ', DATA_COMPRESSION = PAGE' ELSE '' END + ')' ELSE '' END; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start', @Text = @Sql; SET @SizeBefore = (SELECT sum(reserved_page_count) FROM sys.dm_db_partition_stats WHERE object_id = object_id(@TableName) - AND index_id = @IndexId) * 8.0 / 1024 / 1024; + AND index_id = @IndexId + AND partition_number = @PartitionNumber) * 8.0 / 1024 / 1024; SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Text = @msg; BEGIN TRY @@ -1668,7 +1669,8 @@ BEGIN TRY SET @SizeAfter = (SELECT sum(reserved_page_count) FROM sys.dm_db_partition_stats WHERE object_id = object_id(@TableName) - AND index_id = @IndexId) * 8.0 / 1024 / 1024; + AND index_id = @IndexId + AND partition_number = @PartitionNumber) * 8.0 / 1024 / 1024; SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore) + ', after=' + CONVERT (VARCHAR, @SizeAfter) + ', reduced by=' + CONVERT (VARCHAR, @SizeBefore - @SizeAfter); EXECUTE dbo.LogEvent @Process = @SP, @Status = 'End', @Mode = @Mode, @Action = @Operation, @Start = @st, @Text = @msg; END TRY @@ -1718,7 +1720,7 @@ DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @st AS DATETIME = getUTCda WHERE Id = 'Defrag.MinFragPct'), 10), @MinSizeGB AS FLOAT = isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'Defrag.MinSizeGB'), 0.1), @PreviousGroupId AS BIGINT, @IndexId AS INT; -DECLARE @Mode AS VARCHAR (200) = 'T=' + @TableName + ' I=' + isnull(@IndexName, 'NULL') + ' P=' + CONVERT (VARCHAR, @PartitionNumber) + ' MF=' + CONVERT (VARCHAR, @MinFragPct) + ' MS=' + CONVERT (VARCHAR, @MinSizeGB); +DECLARE @Mode AS VARCHAR (200) = 'T=' + @TableName + ' I=' + isnull(@IndexName, 'NULL') + ' P=' + isnull(CONVERT (VARCHAR, @PartitionNumber), 'NULL') + ' MF=' + CONVERT (VARCHAR, @MinFragPct) + ' MS=' + CONVERT (VARCHAR, @MinSizeGB); BEGIN TRY EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; IF object_id(@TableName) IS NULL From 037061d865b447e181b9d58213356bec87e1ca9e Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 31 Oct 2024 15:32:57 -0700 Subject: [PATCH 019/111] Reference separation --- .../Features/Schema/Migrations/84.sql | 180 +++++++++++++----- .../Schema/Sql/Sprocs/MergeResources.sql | 41 ++-- .../Sql/Sprocs/UpdateResourceSearchParams.sql | 19 +- .../Sql/Tables/ReferenceSearchParam.sql | 47 +++-- .../Schema/Sql/Views/ReferenceSearchParam.sql | 21 +- 5 files changed, 218 insertions(+), 90 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 0ef42106a9..4e83f3828b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -540,18 +540,13 @@ CREATE INDEX IX_SearchParamId_QuantityCodeId_HighValue_LowValue_INCLUDE_SystemId ON PartitionScheme_ResourceTypeId (ResourceTypeId); CREATE TABLE dbo.ReferenceSearchParam ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - SearchParamId SMALLINT NOT NULL, - BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, - ReferenceResourceTypeId SMALLINT NOT NULL, - ReferenceResourceIdInt BIGINT CONSTRAINT DF_ReferenceSearchParam_ResourceIdInt DEFAULT 0 NOT NULL, - ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS CONSTRAINT DF_ReferenceSearchParam_ResourceId DEFAULT '' NOT NULL, - ReferenceResourceVersion INT NULL, - CONSTRAINT CH_ReferenceSearchParam_ReferenceResourceIdInt_ReferenceResourceId CHECK (ReferenceResourceIdInt = 0 - AND ReferenceResourceId <> '' - OR ReferenceResourceIdInt <> 0 - AND ReferenceResourceId = '') + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NOT NULL, + ReferenceResourceIdInt BIGINT NOT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL ); @@ -560,24 +555,47 @@ DROP TABLE dbo.ReferenceSearchParam; GO -CREATE TABLE dbo.ReferenceSearchParams ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - SearchParamId SMALLINT NOT NULL, - BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, - ReferenceResourceTypeId SMALLINT NOT NULL, - ReferenceResourceIdInt BIGINT NOT NULL, - ReferenceResourceVersion INT NULL +CREATE TABLE dbo.ResourceReferenceSearchParams ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NOT NULL, + ReferenceResourceIdInt BIGINT NOT NULL, + IsResourceRef BIT CONSTRAINT DF_ResourceReferenceSearchParams_IsResourceRef DEFAULT 1 NOT NULL, + CONSTRAINT CH_ResourceReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 1) ); -ALTER TABLE dbo.ReferenceSearchParams SET (LOCK_ESCALATION = AUTO); +ALTER TABLE dbo.ResourceReferenceSearchParams SET (LOCK_ESCALATION = AUTO); CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId - ON dbo.ReferenceSearchParams(ResourceSurrogateId, SearchParamId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON dbo.ResourceReferenceSearchParams(ResourceSurrogateId, SearchParamId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId); CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId - ON dbo.ReferenceSearchParams(ReferenceResourceIdInt, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON dbo.ResourceReferenceSearchParams(ReferenceResourceIdInt, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + + +GO +CREATE TABLE dbo.StringReferenceSearchParams ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + IsResourceRef BIT CONSTRAINT DF_StringReferenceSearchParams_IsResourceRef DEFAULT 0 NOT NULL, + CONSTRAINT CH_StringReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 0) +); + +ALTER TABLE dbo.StringReferenceSearchParams SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.StringReferenceSearchParams(ResourceSurrogateId, SearchParamId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE INDEX IXU_ReferenceResourceId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.StringReferenceSearchParams(ReferenceResourceId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId); CREATE TABLE dbo.ReferenceTokenCompositeSearchParam ( @@ -3572,13 +3590,12 @@ BEGIN TRY OffsetInFile INT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), UNIQUE (ResourceTypeId, ResourceIdInt, Version)); DECLARE @ReferenceSearchParamsWithIds AS TABLE ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - SearchParamId SMALLINT NOT NULL, - BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, - ReferenceResourceTypeId SMALLINT NULL, - ReferenceResourceIdInt BIGINT NOT NULL, - ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt)); + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NOT NULL, + ReferenceResourceIdInt BIGINT NOT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt)); INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId @@ -3629,14 +3646,13 @@ BEGIN TRY DELETE @RTs WHERE ResourceTypeId = @RT; END - INSERT INTO @ReferenceSearchParamsWithIds (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + INSERT INTO @ReferenceSearchParamsWithIds (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - isnull(C.ResourceIdInt, B.ResourceIdInt), - ReferenceResourceVersion + isnull(C.ResourceIdInt, B.ResourceIdInt) FROM (SELECT * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL) AS A @@ -3871,7 +3887,13 @@ BEGIN TRY FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; - DELETE dbo.ReferenceSearchParams + DELETE dbo.ResourceReferenceSearchParams + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.StringReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId @@ -3977,16 +3999,24 @@ BEGIN TRY ClaimValue FROM @ResourceWriteClaims; SET @AffectedRows += @@rowcount; - INSERT INTO dbo.ReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + INSERT INTO dbo.ResourceReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - ReferenceResourceIdInt, - ReferenceResourceVersion + ReferenceResourceIdInt FROM @ReferenceSearchParamsWithIds; SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL; + SET @AffectedRows += @@rowcount; INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) SELECT ResourceTypeId, ResourceSurrogateId, @@ -4146,14 +4176,13 @@ BEGIN TRY WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); SET @AffectedRows += @@rowcount; - INSERT INTO dbo.ReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + INSERT INTO dbo.ResourceReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - ReferenceResourceIdInt, - ReferenceResourceVersion + ReferenceResourceIdInt FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParamsWithIds) AS A WHERE EXISTS (SELECT * @@ -4161,7 +4190,26 @@ BEGIN TRY WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) AND NOT EXISTS (SELECT * - FROM dbo.ReferenceSearchParams AS C + FROM dbo.ResourceReferenceSearchParams AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId) + SELECT A.ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceId + FROM (SELECT TOP (@DummyTop) * + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.StringReferenceSearchParams AS C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); @@ -5253,7 +5301,13 @@ BEGIN TRY dbo.ResourceWriteClaim AS B ON B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B - FROM dbo.ReferenceSearchParams AS B + FROM dbo.ResourceReferenceSearchParams AS B + WHERE EXISTS (SELECT * + FROM @Ids AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId); + DELETE B + FROM dbo.StringReferenceSearchParams AS B WHERE EXISTS (SELECT * FROM @Ids AS A WHERE A.ResourceTypeId = B.ResourceTypeId @@ -5341,19 +5395,26 @@ BEGIN TRY ClaimTypeId, ClaimValue FROM @ResourceWriteClaims; - INSERT INTO dbo.ReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + INSERT INTO dbo.ResourceReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - B.ResourceIdInt, - ReferenceResourceVersion + B.ResourceIdInt FROM @ReferenceSearchParams AS A INNER JOIN dbo.ResourceIdIntMap AS B - ON B.ResourceTypeId = A.ResourceTypeId + ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId; + INSERT INTO dbo.StringReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL; INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) SELECT ResourceTypeId, ResourceSurrogateId, @@ -5534,12 +5595,21 @@ SELECT A.ResourceTypeId, BaseUri, ReferenceResourceTypeId, B.ResourceId AS ReferenceResourceId, - ReferenceResourceVersion -FROM dbo.ReferenceSearchParams AS A + IsResourceRef +FROM dbo.ResourceReferenceSearchParams AS A LEFT OUTER JOIN dbo.ResourceIdIntMap AS B ON B.ResourceTypeId = A.ReferenceResourceTypeId - AND B.ResourceIdInt = A.ReferenceResourceIdInt; + AND B.ResourceIdInt = A.ReferenceResourceIdInt +UNION ALL +SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + NULL, + ReferenceResourceId, + IsResourceRef +FROM dbo.StringReferenceSearchParams; GO @@ -5548,10 +5618,18 @@ CREATE TRIGGER dbo.ReferenceSearchParamDel INSTEAD OF DELETE AS BEGIN DELETE A - FROM dbo.ReferenceSearchParams AS A + FROM dbo.ResourceReferenceSearchParams AS A WHERE EXISTS (SELECT * FROM Deleted AS B - WHERE B.ResourceTypeId = A.ResourceTypeId + WHERE B.IsResourceRef = 1 + AND B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId); + DELETE A + FROM dbo.StringReferenceSearchParams AS A + WHERE EXISTS (SELECT * + FROM Deleted AS B + WHERE B.IsResourceRef = 0 + AND B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId); END diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 84b765ff53..f92e1da096 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -74,9 +74,8 @@ BEGIN TRY ,ResourceSurrogateId bigint NOT NULL ,SearchParamId smallint NOT NULL ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL - ,ReferenceResourceTypeId smallint NULL + ,ReferenceResourceTypeId smallint NOT NULL ,ReferenceResourceIdInt bigint NOT NULL - ,ReferenceResourceVersion int NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) ) @@ -119,8 +118,8 @@ BEGIN TRY END INSERT INTO @ReferenceSearchParamsWithIds - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) - SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), ReferenceResourceVersion + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) FROM (SELECT * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL) A LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId @@ -292,7 +291,9 @@ BEGIN TRY DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount - DELETE FROM dbo.ReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + DELETE FROM dbo.ResourceReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.StringReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount @@ -336,12 +337,19 @@ BEGIN TRY FROM @ResourceWriteClaims SET @AffectedRows += @@rowcount - INSERT INTO dbo.ReferenceSearchParams - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) - SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt FROM @ReferenceSearchParamsWithIds SET @AffectedRows += @@rowcount + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL + SET @AffectedRows += @@rowcount + INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow @@ -431,12 +439,21 @@ BEGIN TRY OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount - INSERT INTO dbo.ReferenceSearchParams - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) - SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParamsWithIds) A WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) - AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NULL) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.StringReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) SET @AffectedRows += @@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql index fdee25590e..ba423b78e6 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql @@ -39,7 +39,8 @@ BEGIN TRY -- First, delete all the search params of the resources to reindex. DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM dbo.ReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + DELETE FROM B FROM dbo.ResourceReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + DELETE FROM B FROM dbo.StringReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId @@ -60,11 +61,19 @@ BEGIN TRY SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims - INSERT INTO dbo.ReferenceSearchParams - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) - SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, B.ResourceIdInt, ReferenceResourceVersion + -- TODO: Add insert into ResourceIdIntMap + + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, B.ResourceIdInt FROM @ReferenceSearchParams A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ReferenceResourceId + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL INSERT INTO dbo.TokenSearchParam ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index 2c3d9b0e1d..35742143bc 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -5,16 +5,13 @@ ,SearchParamId smallint NOT NULL ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL ,ReferenceResourceTypeId smallint NOT NULL - ,ReferenceResourceIdInt bigint NOT NULL CONSTRAINT DF_ReferenceSearchParam_ResourceIdInt DEFAULT 0 - ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT DF_ReferenceSearchParam_ResourceId DEFAULT '' - ,ReferenceResourceVersion int NULL - - ,CONSTRAINT CH_ReferenceSearchParam_ReferenceResourceIdInt_ReferenceResourceId CHECK (ReferenceResourceIdInt = 0 AND ReferenceResourceId <> '' OR ReferenceResourceIdInt <> 0 AND ReferenceResourceId = '') + ,ReferenceResourceIdInt bigint NOT NULL + ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ) GO DROP TABLE dbo.ReferenceSearchParam GO -CREATE TABLE dbo.ReferenceSearchParams +CREATE TABLE dbo.ResourceReferenceSearchParams ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL @@ -22,22 +19,36 @@ CREATE TABLE dbo.ReferenceSearchParams ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL ,ReferenceResourceTypeId smallint NOT NULL ,ReferenceResourceIdInt bigint NOT NULL - ,ReferenceResourceVersion int NULL + ,IsResourceRef bit NOT NULL CONSTRAINT DF_ResourceReferenceSearchParams_IsResourceRef DEFAULT 1, CONSTRAINT CH_ResourceReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 1) +) + +ALTER TABLE dbo.ResourceReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) + +CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.ResourceReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + +CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.ResourceReferenceSearchParams (ReferenceResourceIdInt, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +GO +CREATE TABLE dbo.StringReferenceSearchParams +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,IsResourceRef bit NOT NULL CONSTRAINT DF_StringReferenceSearchParams_IsResourceRef DEFAULT 0, CONSTRAINT CH_StringReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 0) ) -ALTER TABLE dbo.ReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) +ALTER TABLE dbo.StringReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) -CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId ON dbo.ReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) +CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.StringReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId ON dbo.ReferenceSearchParams - ( - ReferenceResourceIdInt - ,ReferenceResourceTypeId - ,SearchParamId - ,BaseUri - ,ResourceSurrogateId - ,ResourceTypeId - ) +CREATE UNIQUE INDEX IXU_ReferenceResourceId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.StringReferenceSearchParams (ReferenceResourceId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql index 933314186d..e0a5710bc8 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql @@ -6,15 +6,28 @@ SELECT A.ResourceTypeId ,BaseUri ,ReferenceResourceTypeId ,ReferenceResourceId = B.ResourceId - ,ReferenceResourceVersion - FROM dbo.ReferenceSearchParams A + ,IsResourceRef + FROM dbo.ResourceReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,NULL + ,ReferenceResourceId + ,IsResourceRef + FROM dbo.StringReferenceSearchParams GO CREATE TRIGGER dbo.ReferenceSearchParamDel ON dbo.ReferenceSearchParam INSTEAD OF DELETE AS BEGIN DELETE FROM A - FROM dbo.ReferenceSearchParams A - WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) + FROM dbo.ResourceReferenceSearchParams A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.IsResourceRef = 1 AND B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) + + DELETE FROM A + FROM dbo.StringReferenceSearchParams A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.IsResourceRef = 0 AND B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) END GO From 99c6620f39c1fb397d7bf119a9b78238f123f7a9 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 31 Oct 2024 20:57:28 -0700 Subject: [PATCH 020/111] file id --- .../Features/Schema/Migrations/84.sql | 152 +++++++----------- .../Schema/Sql/Sprocs/GetResources.sql | 8 +- .../Sprocs/GetResourcesByTransactionId.sql | 31 +--- .../GetResourcesByTypeAndSurrogateIdRange.sql | 4 +- .../Schema/Sql/Sprocs/MergeResources.sql | 4 +- .../MergeResourcesDeleteInvisibleHistory.sql | 19 +-- .../Features/Schema/Sql/Tables/Resource.sql | 45 +++--- .../Features/Schema/Sql/Views/Resource.sql | 10 +- .../Features/Search/SqlServerSearchService.cs | 12 +- .../Storage/SqlServerFhirDataStore.cs | 4 +- .../Features/Storage/SqlStoreClient.cs | 16 +- .../InvisibleHistoryCleanupWatchdog.cs | 6 +- 12 files changed, 127 insertions(+), 184 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 4e83f3828b..da5050d29b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -635,27 +635,6 @@ CREATE TABLE dbo.ReindexJob ( CONSTRAINT PKC_ReindexJob PRIMARY KEY CLUSTERED (Id) ); -CREATE TABLE dbo.ResourceIdIntMap ( - ResourceTypeId SMALLINT NOT NULL, - ResourceIdInt BIGINT NOT NULL, - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -); - -ALTER TABLE dbo.ResourceIdIntMap SET (LOCK_ESCALATION = AUTO); - - -GO -CREATE TABLE dbo.RawResources ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - RawResource VARBINARY (MAX) NULL CONSTRAINT PKC_RawResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -); - -ALTER TABLE dbo.RawResources SET (LOCK_ESCALATION = AUTO); - - -GO CREATE TABLE dbo.Resource ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL, @@ -669,6 +648,7 @@ CREATE TABLE dbo.Resource ( SearchParamHash VARCHAR (64) NULL, TransactionId BIGINT NULL, HistoryTransactionId BIGINT NULL, + FileId BIGINT NULL, OffsetInFile INT NULL ); @@ -677,6 +657,27 @@ GO DROP TABLE dbo.Resource; +GO +CREATE TABLE dbo.ResourceIdIntMap ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.ResourceIdIntMap SET (LOCK_ESCALATION = AUTO); + + +GO +CREATE TABLE dbo.RawResources ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + RawResource VARBINARY (MAX) NULL CONSTRAINT PKC_RawResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.RawResources SET (LOCK_ESCALATION = AUTO); + + GO CREATE TABLE dbo.CurrentResources ( ResourceTypeId SMALLINT NOT NULL, @@ -690,6 +691,7 @@ CREATE TABLE dbo.CurrentResources ( SearchParamHash VARCHAR (64) NULL, TransactionId BIGINT NULL, HistoryTransactionId BIGINT NULL, + FileId BIGINT NULL, OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) @@ -719,6 +721,7 @@ CREATE TABLE dbo.HistoryResources ( SearchParamHash VARCHAR (64) NULL, TransactionId BIGINT NULL, HistoryTransactionId BIGINT NULL, + FileId BIGINT NULL, OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1), CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) @@ -2861,7 +2864,7 @@ BEGIN TRY RawResource, IsRawResourceMetaSet, SearchParamHash, - TransactionId, + FileId, OffsetInFile FROM (SELECT * FROM @ResourceKeys) AS A @@ -2886,7 +2889,7 @@ BEGIN TRY RawResource, IsRawResourceMetaSet, SearchParamHash, - TransactionId, + FileId, OffsetInFile FROM (SELECT * FROM @ResourceKeys @@ -2910,7 +2913,7 @@ BEGIN TRY RawResource, IsRawResourceMetaSet, SearchParamHash, - TransactionId, + FileId, OffsetInFile FROM (SELECT * FROM @ResourceKeys @@ -2939,7 +2942,7 @@ BEGIN TRY RawResource, IsRawResourceMetaSet, SearchParamHash, - TransactionId, + FileId, OffsetInFile FROM (SELECT * FROM @ResourceKeys) AS A @@ -2970,31 +2973,8 @@ CREATE PROCEDURE dbo.GetResourcesByTransactionId @TransactionId BIGINT, @IncludeHistory BIT=0, @ReturnResourceKeysOnly BIT=0 AS SET NOCOUNT ON; -DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId) + ' H=' + CONVERT (VARCHAR, @IncludeHistory), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807, @TypeId AS SMALLINT; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId) + ' H=' + CONVERT (VARCHAR, @IncludeHistory), @st AS DATETIME = getUTCdate(); BEGIN TRY - DECLARE @Types TABLE ( - TypeId SMALLINT PRIMARY KEY, - Name VARCHAR (100)); - INSERT INTO @Types - EXECUTE dbo.GetUsedResourceTypes ; - DECLARE @Keys TABLE ( - TypeId SMALLINT, - SurrogateId BIGINT PRIMARY KEY (TypeId, SurrogateId)); - WHILE EXISTS (SELECT * - FROM @Types) - BEGIN - SET @TypeId = (SELECT TOP 1 TypeId - FROM @Types - ORDER BY TypeId); - INSERT INTO @Keys - SELECT @TypeId, - ResourceSurrogateId - FROM dbo.Resource - WHERE ResourceTypeId = @TypeId - AND TransactionId = @TransactionId; - DELETE @Types - WHERE TypeId = @TypeId; - END IF @ReturnResourceKeysOnly = 0 SELECT ResourceTypeId, ResourceId, @@ -3006,32 +2986,24 @@ BEGIN TRY IsRawResourceMetaSet, SearchParamHash, RequestMethod, - TransactionId, + FileId, OffsetInFile - FROM (SELECT TOP (@DummyTop) * - FROM @Keys) AS A - INNER JOIN - dbo.Resource AS B - ON ResourceTypeId = TypeId - AND ResourceSurrogateId = SurrogateId - WHERE IsHistory = 0 - OR @IncludeHistory = 1 - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + FROM dbo.Resource + WHERE TransactionId = @TransactionId + AND (IsHistory = 0 + OR @IncludeHistory = 1) + OPTION (MAXDOP 1); ELSE SELECT ResourceTypeId, ResourceId, ResourceSurrogateId, Version, IsDeleted - FROM (SELECT TOP (@DummyTop) * - FROM @Keys) AS A - INNER JOIN - dbo.Resource AS B - ON ResourceTypeId = TypeId - AND ResourceSurrogateId = SurrogateId - WHERE IsHistory = 0 - OR @IncludeHistory = 1 - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + FROM dbo.Resource + WHERE TransactionId = @TransactionId + AND (IsHistory = 0 + OR @IncludeHistory = 1) + OPTION (MAXDOP 1); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; END TRY BEGIN CATCH @@ -3090,7 +3062,7 @@ BEGIN TRY IsRawResourceMetaSet, SearchParamHash, RawResource, - TransactionId, + FileId, OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId @@ -3111,7 +3083,7 @@ BEGIN TRY IsRawResourceMetaSet, SearchParamHash, RawResource, - TransactionId, + FileId, OffsetInFile FROM @SurrogateIds INNER JOIN @@ -3978,7 +3950,7 @@ BEGIN TRY AND SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; END - INSERT INTO dbo.Resource (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile) + INSERT INTO dbo.Resource (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile) SELECT ResourceTypeId, ResourceIdInt, Version, @@ -3990,6 +3962,7 @@ BEGIN TRY IsRawResourceMetaSet, SearchParamHash, @TransactionId, + @TransactionId, OffsetInFile FROM @ResourcesWithIds; SET @AffectedRows += @@rowcount; @@ -4645,26 +4618,15 @@ SET NOCOUNT ON; DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(), @TypeId AS SMALLINT; SET @AffectedRows = 0; BEGIN TRY - DECLARE @Types TABLE ( - TypeId SMALLINT PRIMARY KEY, - Name VARCHAR (100)); - INSERT INTO @Types - EXECUTE dbo.GetUsedResourceTypes ; - WHILE EXISTS (SELECT * - FROM @Types) - BEGIN - SET @TypeId = (SELECT TOP 1 TypeId - FROM @Types - ORDER BY TypeId); - DELETE dbo.Resource - WHERE ResourceTypeId = @TypeId - AND HistoryTransactionId = @TransactionId - AND RawResource = 0xF; - SET @AffectedRows += @@rowcount; - DELETE @Types - WHERE TypeId = @TypeId; - END - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; + DELETE dbo.Resource + WHERE HistoryTransactionId = @TransactionId + AND RawResource = 0xF; + SET @AffectedRows += @@rowcount; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Start = @st, @Rows = @AffectedRows; + UPDATE dbo.Resource + SET TransactionId = NULL + WHERE TransactionId = @TransactionId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Target = 'Resource', @Action = 'Update', @Start = @st, @Rows = @@rowcount; END TRY BEGIN CATCH IF error_number() = 1750 @@ -5649,6 +5611,7 @@ SELECT A.ResourceTypeId, SearchParamHash, TransactionId, HistoryTransactionId, + FileId, OffsetInFile FROM dbo.CurrentResources AS A LEFT OUTER JOIN @@ -5673,6 +5636,7 @@ SELECT A.ResourceTypeId, SearchParamHash, TransactionId, HistoryTransactionId, + FileId, OffsetInFile FROM dbo.HistoryResources AS A LEFT OUTER JOIN @@ -5696,7 +5660,7 @@ CREATE TRIGGER dbo.ResourceIns RawResource FROM Inserted WHERE RawResource IS NOT NULL; - INSERT INTO dbo.CurrentResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile) + INSERT INTO dbo.CurrentResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile) SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, @@ -5707,10 +5671,11 @@ CREATE TRIGGER dbo.ResourceIns SearchParamHash, TransactionId, HistoryTransactionId, + FileId, OffsetInFile FROM Inserted WHERE IsHistory = 0; - INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile) + INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile) SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, @@ -5721,6 +5686,7 @@ CREATE TRIGGER dbo.ResourceIns SearchParamHash, TransactionId, HistoryTransactionId, + FileId, OffsetInFile FROM Inserted WHERE IsHistory = 1; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index 310b27dece..5e3ab4aa0f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -27,7 +27,7 @@ BEGIN TRY ,RawResource ,IsRawResourceMetaSet ,SearchParamHash - ,TransactionId + ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId @@ -44,7 +44,7 @@ BEGIN TRY ,RawResource ,IsRawResourceMetaSet ,SearchParamHash - ,TransactionId + ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId @@ -59,7 +59,7 @@ BEGIN TRY ,RawResource ,IsRawResourceMetaSet ,SearchParamHash - ,TransactionId + ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId @@ -77,7 +77,7 @@ BEGIN TRY ,RawResource ,IsRawResourceMetaSet ,SearchParamHash - ,TransactionId + ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql index e149e1d617..85d93fbd35 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTransactionId.sql @@ -6,23 +6,8 @@ set nocount on DECLARE @SP varchar(100) = object_name(@@procid) ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId)+' H='+convert(varchar,@IncludeHistory) ,@st datetime = getUTCdate() - ,@DummyTop bigint = 9223372036854775807 - ,@TypeId smallint BEGIN TRY - DECLARE @Types TABLE (TypeId smallint PRIMARY KEY, Name varchar(100)) - INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes - - DECLARE @Keys TABLE (TypeId smallint, SurrogateId bigint PRIMARY KEY (TypeId, SurrogateId)) - WHILE EXISTS (SELECT * FROM @Types) - BEGIN - SET @TypeId = (SELECT TOP 1 TypeId FROM @Types ORDER BY TypeId) - - INSERT INTO @Keys SELECT @TypeId, ResourceSurrogateId FROM dbo.Resource WHERE ResourceTypeId = @TypeId AND TransactionId = @TransactionId - - DELETE FROM @Types WHERE TypeId = @TypeId - END - IF @ReturnResourceKeysOnly = 0 SELECT ResourceTypeId ,ResourceId @@ -34,22 +19,20 @@ BEGIN TRY ,IsRawResourceMetaSet ,SearchParamHash ,RequestMethod - ,TransactionId + ,FileId ,OffsetInFile - FROM (SELECT TOP (@DummyTop) * FROM @Keys) A - JOIN dbo.Resource B ON ResourceTypeId = TypeId AND ResourceSurrogateId = SurrogateId - WHERE IsHistory = 0 OR @IncludeHistory = 1 - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + FROM dbo.Resource + WHERE TransactionId = @TransactionId AND (IsHistory = 0 OR @IncludeHistory = 1) + OPTION (MAXDOP 1) ELSE SELECT ResourceTypeId ,ResourceId ,ResourceSurrogateId ,Version ,IsDeleted - FROM (SELECT TOP (@DummyTop) * FROM @Keys) A - JOIN dbo.Resource B ON ResourceTypeId = TypeId AND ResourceSurrogateId = SurrogateId - WHERE IsHistory = 0 OR @IncludeHistory = 1 - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + FROM dbo.Resource + WHERE TransactionId = @TransactionId AND (IsHistory = 0 OR @IncludeHistory = 1) + OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount END TRY diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql index c18f8e5c9f..57bf64bde7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql @@ -42,14 +42,14 @@ BEGIN TRY OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) END - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, TransactionId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND (IsHistory = 0 OR @IncludeHistory = 1) AND (IsDeleted = 0 OR @IncludeDeleted = 1) UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, TransactionId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index f92e1da096..69c256a897 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -326,8 +326,8 @@ BEGIN TRY END INSERT INTO dbo.Resource - ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, OffsetInFile ) - SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, OffsetInFile + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, @TransactionId, OffsetInFile FROM @ResourcesWithIds SET @AffectedRows += @@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql index 9ae6120539..bf43c913be 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql @@ -11,20 +11,13 @@ DECLARE @SP varchar(100) = object_name(@@procid) SET @AffectedRows = 0 BEGIN TRY - DECLARE @Types TABLE (TypeId smallint PRIMARY KEY, Name varchar(100)) - INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes + DELETE FROM dbo.Resource WHERE HistoryTransactionId = @TransactionId AND RawResource = 0xF + SET @AffectedRows += @@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@AffectedRows - WHILE EXISTS (SELECT * FROM @Types) - BEGIN - SET @TypeId = (SELECT TOP 1 TypeId FROM @Types ORDER BY TypeId) - - DELETE FROM dbo.Resource WHERE ResourceTypeId = @TypeId AND HistoryTransactionId = @TransactionId AND RawResource = 0xF - SET @AffectedRows += @@rowcount - - DELETE FROM @Types WHERE TypeId = @TypeId - END - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows + -- TODO: Move to a separate stored procedure? + UPDATE dbo.Resource SET TransactionId = NULL WHERE TransactionId = @TransactionId + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Target='Resource',@Action='Update',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql index 61afd3b2da..a0ac31447e 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql @@ -1,4 +1,24 @@ -CREATE TABLE dbo.ResourceIdIntMap +CREATE TABLE dbo.Resource +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,Version int NOT NULL + ,IsHistory bit NOT NULL + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL + ,FileId bigint NULL + ,OffsetInFile int NULL +) +GO +DROP TABLE dbo.Resource +GO +CREATE TABLE dbo.ResourceIdIntMap ( ResourceTypeId smallint NOT NULL ,ResourceIdInt bigint NOT NULL @@ -21,25 +41,6 @@ CREATE TABLE dbo.RawResources ALTER TABLE dbo.RawResources SET ( LOCK_ESCALATION = AUTO ) GO -CREATE TABLE dbo.Resource -( - ResourceTypeId smallint NOT NULL - ,ResourceSurrogateId bigint NOT NULL - ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL - ,Version int NOT NULL - ,IsHistory bit NOT NULL - ,IsDeleted bit NOT NULL - ,RequestMethod varchar(10) NULL - ,RawResource varbinary(max) NULL - ,IsRawResourceMetaSet bit NOT NULL - ,SearchParamHash varchar(64) NULL - ,TransactionId bigint NULL - ,HistoryTransactionId bigint NULL - ,OffsetInFile int NULL -) -GO -DROP TABLE dbo.Resource -GO CREATE TABLE dbo.CurrentResources ( ResourceTypeId smallint NOT NULL @@ -53,11 +54,11 @@ CREATE TABLE dbo.CurrentResources ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL ,HistoryTransactionId bigint NULL + ,FileId bigint NULL ,OffsetInFile int NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - --,CONSTRAINT CH_CurrentResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) ) ALTER TABLE dbo.CurrentResources SET ( LOCK_ESCALATION = AUTO ) @@ -78,11 +79,11 @@ CREATE TABLE dbo.HistoryResources ,SearchParamHash varchar(64) NULL ,TransactionId bigint NULL ,HistoryTransactionId bigint NULL + ,FileId bigint NULL ,OffsetInFile int NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - --,CONSTRAINT CH_HistoryResources_RawResource_OffsetInFile CHECK (RawResource IS NOT NULL OR OffsetInFile IS NOT NULL) ) ALTER TABLE dbo.HistoryResources SET ( LOCK_ESCALATION = AUTO ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql index bc6a3c6f9c..1cb0b6b9ca 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -13,6 +13,7 @@ SELECT A.ResourceTypeId ,SearchParamHash ,TransactionId ,HistoryTransactionId + ,FileId ,OffsetInFile FROM dbo.CurrentResources A LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId @@ -31,6 +32,7 @@ SELECT A.ResourceTypeId ,SearchParamHash ,TransactionId ,HistoryTransactionId + ,FileId ,OffsetInFile FROM dbo.HistoryResources A LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId @@ -46,14 +48,14 @@ BEGIN WHERE RawResource IS NOT NULL INSERT INTO dbo.CurrentResources - ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile FROM Inserted WHERE IsHistory = 0 INSERT INTO dbo.HistoryResources - ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile FROM Inserted WHERE IsHistory = 1 END diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index ef9dea5faa..6120eb9fa1 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -435,7 +435,7 @@ await _sqlRetryService.ExecuteSql( out bool isRawResourceMetaSet, out string searchParameterHash, out SqlBytes rawResourceSqlBytes, - out long? transactionId, + out long? fileId, out int? offsetInFile, out bool isInvisible); @@ -461,7 +461,7 @@ await _sqlRetryService.ExecuteSql( { rawResource = new Lazy(() => { - var decompressedResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); + var decompressedResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, fileId, offsetInFile); _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(resourceSurrogateId), resourceSurrogateId, nameof(resourceTypeId), resourceTypeId, decompressedResource.Length); @@ -649,7 +649,7 @@ await _sqlRetryService.ExecuteSql( out bool isRawResourceMetaSet, out string searchParameterHash, out SqlBytes rawResourceSqlBytes, - out long? transactionId, + out long? fileId, out int? offsetInFile, out bool isInvisible); @@ -664,7 +664,7 @@ await _sqlRetryService.ExecuteSql( continue; } - var rawResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, transactionId, offsetInFile); + var rawResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, fileId, offsetInFile); if (string.IsNullOrEmpty(rawResource)) { @@ -837,7 +837,7 @@ private void ReadWrapper( out bool isRawResourceMetaSet, out string searchParameterHash, out SqlBytes rawResourceSqlBytes, - out long? transactionId, + out long? fileId, out int? offsetInFile, out bool isInvisible) { @@ -852,7 +852,7 @@ private void ReadWrapper( isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 8); searchParameterHash = reader.Read(VLatest.Resource.SearchParamHash, 9); rawResourceSqlBytes = reader.GetSqlBytes(10); - transactionId = reader.Read(VLatest.Resource.TransactionId, 11); + fileId = reader.Read(VLatest.Resource.FileId, 11); offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, 12); isInvisible = false; if (!rawResourceSqlBytes.IsNull) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index a91d88b0db..6575c79b9b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -169,9 +169,9 @@ private async Task PutRawResourcesIntoAdls(IReadOnlyList r await StoreClient.TryLogEvent("PutRawResourcesToAdls", "Warn", $"mcsec={mcsec} Resources={resources.Count}", start, cancellationToken); } - internal static string GetBlobNameForRaw(long transactionId) + internal static string GetBlobNameForRaw(long fileId) { - return $"hash-{GetPermanentHashCode(transactionId)}/transaction-{transactionId}.ndjson"; + return $"hash-{GetPermanentHashCode(fileId)}/transaction-{fileId}.ndjson"; } private static string GetPermanentHashCode(long tr) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 5357d0e7e2..1f935c9589 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -94,11 +94,11 @@ public async Task> GetAsync(IReadOnlyList GetRawResourceFromAdls(long transactionId, int offsetInFile) + public static Lazy GetRawResourceFromAdls(long fileId, int offsetInFile) { return new Lazy(() => { - var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(transactionId); + var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(fileId); using var reader = new StreamReader(SqlAdlsStore.AdlsClient.GetBlobClient(blobName).OpenRead(offsetInFile)); var line = reader.ReadLine(); return line; @@ -130,9 +130,9 @@ public static Lazy GetRawResourceFromAdls(long transactionId, int offset { matchedVersion = reader.Read(table.Version, 4).ToString(); var bytes = reader.GetSqlBytes(5); - var matchedTransactionId = reader.Read(table.TransactionId, 6); + var matchedFileId = reader.Read(table.FileId, 6); var matchedOffsetInFile = reader.Read(table.OffsetInFile, 7); - matchedRawResource = new RawResource(ReadRawResource(bytes, decompress, matchedTransactionId, matchedOffsetInFile), FhirResourceFormat.Json, true); + matchedRawResource = new RawResource(ReadRawResource(bytes, decompress, matchedFileId, matchedOffsetInFile), FhirResourceFormat.Json, true); } return (new ResourceDateKey(resourceTypeId, resourceId, resourceSurrogateId, version.ToString(CultureInfo.InvariantCulture)), (matchedVersion, matchedRawResource)); @@ -142,13 +142,13 @@ public static Lazy GetRawResourceFromAdls(long transactionId, int offset return resources; } - internal static string ReadRawResource(SqlBytes bytes, Func decompress, long? transactionId, int? offsetInFile) + internal static string ReadRawResource(SqlBytes bytes, Func decompress, long? fileId, int? offsetInFile) { var rawResourceBytes = bytes.IsNull ? null : bytes.Value; string rawResource; if (rawResourceBytes == null && offsetInFile.HasValue) // raw in adls { - rawResource = GetRawResourceFromAdls(transactionId.Value, offsetInFile.Value).Value; + rawResource = GetRawResourceFromAdls(fileId.Value, offsetInFile.Value).Value; } else if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) // invisible resource { @@ -180,9 +180,9 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re var isDeleted = reader.Read(VLatest.Resource.IsDeleted, 4); var isHistory = reader.Read(VLatest.Resource.IsHistory, 5); var bytes = reader.GetSqlBytes(6); - var transactionId = reader.Read(VLatest.Resource.TransactionId, readRequestMethod ? 10 : 9); + var fileId = reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9); var offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10); - var rawResource = ReadRawResource(bytes, decompress, transactionId.Value, offsetInFile); + var rawResource = ReadRawResource(bytes, decompress, fileId.Value, offsetInFile); var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); var searchParamHash = reader.Read(VLatest.Resource.SearchParamHash, 8); var requestMethod = readRequestMethod ? reader.Read(VLatest.Resource.RequestMethod, 9) : null; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/InvisibleHistoryCleanupWatchdog.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/InvisibleHistoryCleanupWatchdog.cs index 7efa16a6c7..1369046c22 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/InvisibleHistoryCleanupWatchdog.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Watchdogs/InvisibleHistoryCleanupWatchdog.cs @@ -51,8 +51,7 @@ protected override async Task RunWorkAsync(CancellationToken cancellationToken) var visibility = await _store.MergeResourcesGetTransactionVisibilityAsync(cancellationToken); _logger.LogInformation($"{Name}: last cleaned up transaction={lastTranId} visibility={visibility}."); - IReadOnlyList<(long TransactionId, DateTime? VisibleDate, DateTime? InvisibleHistoryRemovedDate)> transToClean = - await _store.GetTransactionsAsync(lastTranId, visibility, cancellationToken, DateTime.UtcNow.AddDays(-1 * RetentionPeriodDays)); + var transToClean = await _store.GetTransactionsAsync(lastTranId, visibility, cancellationToken, DateTime.UtcNow.AddDays(-1 * RetentionPeriodDays)); _logger.LogInformation($"{Name}: found transactions={transToClean.Count}."); @@ -63,8 +62,7 @@ protected override async Task RunWorkAsync(CancellationToken cancellationToken) } var totalRows = 0; - foreach ((long TransactionId, DateTime? VisibleDate, DateTime? InvisibleHistoryRemovedDate) tran in - transToClean.Where(x => !x.InvisibleHistoryRemovedDate.HasValue).OrderBy(x => x.TransactionId)) + foreach (var tran in transToClean.Where(x => !x.InvisibleHistoryRemovedDate.HasValue).OrderBy(x => x.TransactionId)) { var rows = await _store.MergeResourcesDeleteInvisibleHistory(tran.TransactionId, cancellationToken); _logger.LogInformation($"{Name}: transaction={tran.TransactionId} removed rows={rows}."); From 0b226bf1ddd3649c219e22341e3ce8cdabfc939e Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 1 Nov 2024 14:32:22 -0700 Subject: [PATCH 021/111] small things --- .../Features/Schema/Migrations/84.sql | 2 +- .../Features/Schema/Sql/Tables/ReferenceSearchParam.sql | 2 +- .../Features/Storage/SqlStoreClient.cs | 2 +- 3 files changed, 3 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index da5050d29b..bf7e30d4c2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -544,7 +544,7 @@ CREATE TABLE dbo.ReferenceSearchParam ( ResourceSurrogateId BIGINT NOT NULL, SearchParamId SMALLINT NOT NULL, BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, - ReferenceResourceTypeId SMALLINT NOT NULL, + ReferenceResourceTypeId SMALLINT NULL, ReferenceResourceIdInt BIGINT NOT NULL, ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL ); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index 35742143bc..a6707cdd27 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -4,7 +4,7 @@ ,ResourceSurrogateId bigint NOT NULL ,SearchParamId smallint NOT NULL ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL - ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceTypeId smallint NULL ,ReferenceResourceIdInt bigint NOT NULL ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 1f935c9589..0372c51313 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -182,7 +182,7 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re var bytes = reader.GetSqlBytes(6); var fileId = reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9); var offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10); - var rawResource = ReadRawResource(bytes, decompress, fileId.Value, offsetInFile); + var rawResource = ReadRawResource(bytes, decompress, fileId, offsetInFile); var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); var searchParamHash = reader.Read(VLatest.Resource.SearchParamHash, 8); var requestMethod = readRequestMethod ? reader.Read(VLatest.Resource.RequestMethod, 9) : null; From 7f286f92d158f4d35cb9ca9d253e0dd2c78bce7e Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 7 Nov 2024 14:47:56 -0800 Subject: [PATCH 022/111] Do not write raw resource --- .../Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs index 4a97b5f63f..fb2fb796a2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs @@ -34,7 +34,8 @@ public IEnumerable GenerateRows(IReadOnlyList Date: Mon, 18 Nov 2024 14:36:58 -0800 Subject: [PATCH 023/111] Added missing file id in history insert --- .../Features/Schema/Migrations/84.sql | 3 ++- .../Features/Schema/Sql/Views/Resource.sql | 4 ++-- 2 files changed, 4 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index bf7e30d4c2..9d31a0e42d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -5768,7 +5768,7 @@ CREATE TRIGGER dbo.ResourceUpd WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1); - INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile) + INSERT INTO dbo.HistoryResources (ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile) SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, @@ -5779,6 +5779,7 @@ CREATE TRIGGER dbo.ResourceUpd SearchParamHash, TransactionId, HistoryTransactionId, + FileId, OffsetInFile FROM Inserted WHERE IsHistory = 1; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql index 1cb0b6b9ca..d5642edb15 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -121,8 +121,8 @@ BEGIN WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) INSERT INTO dbo.HistoryResources - ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, OffsetInFile + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile FROM Inserted WHERE IsHistory = 1 END From ce2889144e2c49c1a28de23a0825b98fa56fd245 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 18 Nov 2024 16:08:22 -0800 Subject: [PATCH 024/111] hard delete tests --- .../Features/Schema/Migrations/84.sql | 34 ++++++------------- .../Schema/Sql/Sprocs/HardDeleteResource.sql | 28 ++++++--------- .../SqlServerFhirStorageTestHelper.cs | 5 +-- 3 files changed, 23 insertions(+), 44 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 9d31a0e42d..edefafa633 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -3300,30 +3300,16 @@ BEGIN TRY BEGIN TRANSACTION; DECLARE @SurrogateIds TABLE ( ResourceSurrogateId BIGINT NOT NULL); - IF @IsResourceChangeCaptureEnabled = 1 - AND NOT EXISTS (SELECT * - FROM dbo.Parameters - WHERE Id = 'InvisibleHistory.IsEnabled' - AND Number = 0) - UPDATE dbo.Resource - SET IsDeleted = 1, - RawResource = 0xF, - SearchParamHash = NULL, - HistoryTransactionId = @TransactionId - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 - OR IsHistory = 1) - AND RawResource <> 0xF; - ELSE - DELETE dbo.Resource - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 - OR IsHistory = 1) - AND RawResource <> 0xF; + UPDATE dbo.Resource + SET IsDeleted = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1); IF @KeepCurrentVersion = 0 BEGIN DELETE B diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql index 9dad047285..52e82f0aa3 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql @@ -18,24 +18,16 @@ BEGIN TRY DECLARE @SurrogateIds TABLE (ResourceSurrogateId BIGINT NOT NULL) - IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) - UPDATE dbo.Resource - SET IsDeleted = 1 - ,RawResource = 0xF -- invisible value - ,SearchParamHash = NULL - ,HistoryTransactionId = @TransactionId - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 OR IsHistory = 1) - AND RawResource <> 0xF - ELSE - DELETE dbo.Resource - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 OR IsHistory = 1) - AND RawResource <> 0xF + UPDATE dbo.Resource + SET IsDeleted = 1 + ,RawResource = 0xF -- invisible value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) + --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS IF @KeepCurrentVersion = 0 BEGIN diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs index 8c1d11062d..11697ffbd0 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs @@ -322,7 +322,7 @@ async Task IFhirStorageTestHelper.ValidateSnapshotTokenIsCurrent(object snapshot { outerCommand.CommandText = @" SELECT t.name - FROM (SELECT name, object_id FROM sys.objects WHERE name NOT IN ('ResourceCurrent', 'ResourceHistory') AND type IN ('u','v')) t + FROM (SELECT name, object_id FROM sys.objects WHERE name NOT IN ('CurrentResources', 'HistoryResources', 'RawResources') AND type IN ('u','v')) t JOIN sys.columns c ON c.object_id = t.object_id WHERE c.name = 'ResourceSurrogateId'"; @@ -336,7 +336,8 @@ SELECT t.name } string tableName = reader.GetString(0); - sb.AppendLine($"SELECT '{tableName}' as TableName, MAX(ResourceSurrogateId) as MaxResourceSurrogateId FROM dbo.{tableName}"); + var where = tableName == "Resource" ? "WHERE RawResource <> 0xF" : string.Empty; + sb.AppendLine($"SELECT '{tableName}' as TableName, MAX(ResourceSurrogateId) as MaxResourceSurrogateId FROM dbo.{tableName} {where}"); } } } From 848195c6ee79b34bb814094016940b3193f22ff7 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 18 Nov 2024 17:14:19 -0800 Subject: [PATCH 025/111] change capture --- .../Features/Schema/Migrations/84.sql | 21 +++++++++++++++++++ .../Features/Schema/Sql/Views/Resource.sql | 19 +++++++++++++++-- 2 files changed, 38 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index edefafa633..b90106753f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -5728,6 +5728,27 @@ CREATE TRIGGER dbo.ResourceUpd WHERE A.IsHistory = 0; RETURN; END + IF UPDATE (TransactionId) + AND NOT UPDATE (IsHistory) + BEGIN + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted AS A + INNER JOIN + dbo.CurrentResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + AND B.IsHistory = 0; + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted AS A + INNER JOIN + dbo.HistoryResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + AND B.IsHistory = 1; + RETURN; + END IF UPDATE (RawResource) BEGIN UPDATE B diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql index d5642edb15..cd23c932d3 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -63,7 +63,7 @@ GO CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE AS BEGIN - IF UPDATE(IsDeleted) AND UPDATE(RawResource) AND UPDATE(SearchParamHash) AND UPDATE(HistoryTransactionId) AND NOT UPDATE(IsHistory) -- HardDeleteResource + IF UPDATE(IsDeleted) AND UPDATE(RawResource) AND UPDATE(SearchParamHash) AND UPDATE(HistoryTransactionId) AND NOT UPDATE(IsHistory) -- hard delete resource BEGIN UPDATE B SET RawResource = A.RawResource @@ -87,7 +87,7 @@ BEGIN RETURN END - IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) + IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) -- reindex BEGIN UPDATE B SET SearchParamHash = A.SearchParamHash @@ -98,6 +98,21 @@ BEGIN RETURN END + IF UPDATE(TransactionId) AND NOT UPDATE(IsHistory) -- cleanup trans + BEGIN + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted A + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0 + + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted A + JOIN dbo.HistoryResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1 + + RETURN + END + IF UPDATE(RawResource) -- invisible records BEGIN UPDATE B From 61b1c06559b9bd6ef2da35d18a0c328d7e66d866 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 18 Nov 2024 18:37:05 -0800 Subject: [PATCH 026/111] FK --- .../Features/Schema/Migrations/84.sql | 213 +++++++++--------- .../Tables/{Resource.sql => 0_Resource.sql} | 4 + .../Sql/Tables/ReferenceSearchParam.sql | 2 + 3 files changed, 117 insertions(+), 102 deletions(-) rename src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/{Resource.sql => 0_Resource.sql} (93%) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index b90106753f..0bdb2df496 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -259,6 +259,114 @@ CREATE TYPE dbo.UriSearchParamList AS TABLE ( SearchParamId SMALLINT NOT NULL, Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri)); +CREATE TABLE dbo.Resource ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + IsHistory BIT NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + FileId BIGINT NULL, + OffsetInFile INT NULL +); + + +GO +DROP TABLE dbo.Resource; + + +GO +CREATE TABLE dbo.ResourceIdIntMap ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.ResourceIdIntMap SET (LOCK_ESCALATION = AUTO); + + +GO +CREATE TABLE dbo.RawResources ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + RawResource VARBINARY (MAX) NULL CONSTRAINT PKC_RawResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.RawResources SET (LOCK_ESCALATION = AUTO); + + +GO +CREATE TABLE dbo.CurrentResources ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + IsHistory BIT CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0 NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + FileId BIGINT NULL, + OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), + CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.CurrentResources + ADD CONSTRAINT FK_CurrentResources_ResourceIdInt_ResourceTypeId_ResourceIdIntMap FOREIGN KEY (ResourceIdInt, ResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId); + +ALTER TABLE dbo.CurrentResources SET (LOCK_ESCALATION = AUTO); + +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL + ON dbo.CurrentResources(TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL + ON dbo.CurrentResources(HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + + +GO +CREATE TABLE dbo.HistoryResources ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + IsHistory BIT CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1 NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + IsRawResourceMetaSet BIT CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + FileId BIGINT NULL, + OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1), + CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + +ALTER TABLE dbo.HistoryResources + ADD CONSTRAINT FK_HistoryResources_ResourceIdInt_ResourceTypeId_ResourceIdIntMap FOREIGN KEY (ResourceIdInt, ResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId); + +ALTER TABLE dbo.HistoryResources SET (LOCK_ESCALATION = AUTO); + +CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL + ON dbo.HistoryResources(TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL + ON dbo.HistoryResources(HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + CREATE TABLE dbo.ClaimType ( ClaimTypeId TINYINT IDENTITY (1, 1) NOT NULL, Name VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, @@ -566,6 +674,9 @@ CREATE TABLE dbo.ResourceReferenceSearchParams ( CONSTRAINT CH_ResourceReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 1) ); +ALTER TABLE dbo.ResourceReferenceSearchParams + ADD CONSTRAINT FK_ResourceReferenceSearchParams_ReferenceResourceIdInt_ReferenceResourceTypeId_ResourceIdIntMap FOREIGN KEY (ReferenceResourceIdInt, ReferenceResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId); + ALTER TABLE dbo.ResourceReferenceSearchParams SET (LOCK_ESCALATION = AUTO); CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId @@ -635,108 +746,6 @@ CREATE TABLE dbo.ReindexJob ( CONSTRAINT PKC_ReindexJob PRIMARY KEY CLUSTERED (Id) ); -CREATE TABLE dbo.Resource ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, - Version INT NOT NULL, - IsHistory BIT NOT NULL, - IsDeleted BIT NOT NULL, - RequestMethod VARCHAR (10) NULL, - RawResource VARBINARY (MAX) NULL, - IsRawResourceMetaSet BIT NOT NULL, - SearchParamHash VARCHAR (64) NULL, - TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL, - FileId BIGINT NULL, - OffsetInFile INT NULL -); - - -GO -DROP TABLE dbo.Resource; - - -GO -CREATE TABLE dbo.ResourceIdIntMap ( - ResourceTypeId SMALLINT NOT NULL, - ResourceIdInt BIGINT NOT NULL, - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -); - -ALTER TABLE dbo.ResourceIdIntMap SET (LOCK_ESCALATION = AUTO); - - -GO -CREATE TABLE dbo.RawResources ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - RawResource VARBINARY (MAX) NULL CONSTRAINT PKC_RawResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -); - -ALTER TABLE dbo.RawResources SET (LOCK_ESCALATION = AUTO); - - -GO -CREATE TABLE dbo.CurrentResources ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - ResourceIdInt BIGINT NOT NULL, - Version INT NOT NULL, - IsHistory BIT CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0 NOT NULL, - IsDeleted BIT NOT NULL, - RequestMethod VARCHAR (10) NULL, - IsRawResourceMetaSet BIT CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, - SearchParamHash VARCHAR (64) NULL, - TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL, - FileId BIGINT NULL, - OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), - CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -); - -ALTER TABLE dbo.CurrentResources SET (LOCK_ESCALATION = AUTO); - -CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL - ON dbo.CurrentResources(TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - -CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL - ON dbo.CurrentResources(HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - - -GO -CREATE TABLE dbo.HistoryResources ( - ResourceTypeId SMALLINT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - ResourceIdInt BIGINT NOT NULL, - Version INT NOT NULL, - IsHistory BIT CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1 NOT NULL, - IsDeleted BIT NOT NULL, - RequestMethod VARCHAR (10) NULL, - IsRawResourceMetaSet BIT CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 NOT NULL, - SearchParamHash VARCHAR (64) NULL, - TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL, - FileId BIGINT NULL, - OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1), - CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -); - -ALTER TABLE dbo.HistoryResources SET (LOCK_ESCALATION = AUTO); - -CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL - ON dbo.HistoryResources(TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - -CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL - ON dbo.HistoryResources(HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - CREATE TABLE dbo.ResourceChangeData ( Id BIGINT IDENTITY (1, 1) NOT NULL, Timestamp DATETIME2 (7) CONSTRAINT DF_ResourceChangeData_Timestamp DEFAULT sysutcdatetime() NOT NULL, diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql similarity index 93% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql rename to src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql index a0ac31447e..61f5e12435 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql @@ -61,6 +61,8 @@ CREATE TABLE dbo.CurrentResources ,CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) +ALTER TABLE dbo.CurrentResources ADD CONSTRAINT FK_CurrentResources_ResourceIdInt_ResourceTypeId_ResourceIdIntMap FOREIGN KEY (ResourceIdInt, ResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + ALTER TABLE dbo.CurrentResources SET ( LOCK_ESCALATION = AUTO ) CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.CurrentResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) @@ -86,6 +88,8 @@ CREATE TABLE dbo.HistoryResources ,CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) +ALTER TABLE dbo.HistoryResources ADD CONSTRAINT FK_HistoryResources_ResourceIdInt_ResourceTypeId_ResourceIdIntMap FOREIGN KEY (ResourceIdInt, ResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + ALTER TABLE dbo.HistoryResources SET ( LOCK_ESCALATION = AUTO ) CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.HistoryResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index a6707cdd27..2d54387ef5 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -22,6 +22,8 @@ CREATE TABLE dbo.ResourceReferenceSearchParams ,IsResourceRef bit NOT NULL CONSTRAINT DF_ResourceReferenceSearchParams_IsResourceRef DEFAULT 1, CONSTRAINT CH_ResourceReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 1) ) +ALTER TABLE dbo.ResourceReferenceSearchParams ADD CONSTRAINT FK_ResourceReferenceSearchParams_ReferenceResourceIdInt_ReferenceResourceTypeId_ResourceIdIntMap FOREIGN KEY (ReferenceResourceIdInt, ReferenceResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + ALTER TABLE dbo.ResourceReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId From 65b21dcd23e5b84c08de78eb75ce509b82fdcd83 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 19 Nov 2024 08:52:26 -0800 Subject: [PATCH 027/111] Comments --- .../Features/Schema/Sql/Tables/0_Resource.sql | 4 +++- .../Features/Schema/Sql/Tables/ReferenceSearchParam.sql | 3 ++- 2 files changed, 5 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql index 61f5e12435..baf0200463 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql @@ -1,4 +1,6 @@ -CREATE TABLE dbo.Resource +-- 0 in this script name is needed to ensure that this script is executed first, so FK constraints can be created in other scripts +-- Our code generator does not understand views (in the end Resource is a view), so we create a table that looks like a view and immediately drop it. +CREATE TABLE dbo.Resource ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index 2d54387ef5..90b3593491 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -1,4 +1,5 @@ -CREATE TABLE dbo.ReferenceSearchParam +-- Our code generator does not understand views (in the end ReferenceSearchParam is a view), so we create a table that looks like a view and immediately drop it. +CREATE TABLE dbo.ReferenceSearchParam ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL From 2b28ed4b623ec224e0f701001bb9a7cea11f8419 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 20 Nov 2024 14:03:19 -0800 Subject: [PATCH 028/111] resource list lake and 768 --- .../Features/Schema/Migrations/84.sql | 182 +++++++++++++++++- .../Features/Schema/SchemaVersionConstants.cs | 1 + .../Sql/Sprocs/CleanupResourceIdIntMap.sql | 109 +++++++++++ .../Schema/Sql/Sprocs/MergeResources.sql | 24 ++- .../Sql/Tables/ReferenceSearchParam.sql | 4 +- .../Sql/Types/ReferenceSearchParamList.sql | 2 +- .../Schema/Sql/Types/ResourceList.sql | 3 +- .../Schema/Sql/Types/ResourceListLake.sql | 22 +++ .../Storage/SqlServerFhirDataStore.cs | 11 +- .../Merge/ResourceListLakeRowGenerator.cs | 42 ++++ .../Merge/ResourceListRowGenerator.cs | 2 +- 11 files changed, 380 insertions(+), 22 deletions(-) create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 0bdb2df496..4038f446ca 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -109,7 +109,7 @@ CREATE TYPE dbo.ReferenceSearchParamList AS TABLE ( SearchParamId SMALLINT NOT NULL, BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, ReferenceResourceTypeId SMALLINT NULL, - ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceId VARCHAR (768) COLLATE Latin1_General_100_CS_AS NOT NULL, ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId)); CREATE TYPE dbo.ReferenceTokenCompositeSearchParamList AS TABLE ( @@ -135,6 +135,21 @@ CREATE TYPE dbo.ResourceKeyList AS TABLE ( Version INT NULL UNIQUE (ResourceTypeId, ResourceId, Version)); CREATE TYPE dbo.ResourceList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + HasVersionToCompare BIT NOT NULL, + IsDeleted BIT NOT NULL, + IsHistory BIT NOT NULL, + KeepHistory BIT NOT NULL, + RawResource VARBINARY (MAX) NOT NULL, + IsRawResourceMetaSet BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + SearchParamHash VARCHAR (64) NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), + UNIQUE (ResourceTypeId, ResourceId, Version)); + +CREATE TYPE dbo.ResourceListLake AS TABLE ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL, ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, @@ -654,7 +669,7 @@ CREATE TABLE dbo.ReferenceSearchParam ( BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, ReferenceResourceTypeId SMALLINT NULL, ReferenceResourceIdInt BIGINT NOT NULL, - ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL + ReferenceResourceId VARCHAR (768) COLLATE Latin1_General_100_CS_AS NOT NULL ); @@ -694,7 +709,7 @@ CREATE TABLE dbo.StringReferenceSearchParams ( ResourceSurrogateId BIGINT NOT NULL, SearchParamId SMALLINT NOT NULL, BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, - ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceId VARCHAR (768) COLLATE Latin1_General_100_CS_AS NOT NULL, IsResourceRef BIT CONSTRAINT DF_StringReferenceSearchParams_IsResourceRef DEFAULT 0 NOT NULL, CONSTRAINT CH_StringReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 0) ); @@ -1594,6 +1609,119 @@ BEGIN CATCH THROW; END CATCH +GO +CREATE PROCEDURE dbo.CleanupResourceIdIntMap +@ResetAfter BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'CleanupResourceIdIntMap', @Mode AS VARCHAR (100) = 'R=' + isnull(CONVERT (VARCHAR, @ResetAfter), 'NULL'), @st AS DATETIME = getUTCdate(), @Id AS VARCHAR (100) = 'CleanupResourceIdIntMap.LastProcessed.TypeId.ResourceIdInt', @ResourceTypeId AS SMALLINT, @ResourceIdInt AS BIGINT, @RowsToProcess AS INT, @ProcessedRows AS INT = 0, @DeletedRows AS INT = 0, @ReportDate AS DATETIME = getUTCdate(); +DECLARE @LastProcessed AS VARCHAR (100) = isnull((SELECT Char + FROM dbo.Parameters + WHERE Id = @Id), '0.0'); +BEGIN TRY + INSERT INTO dbo.Parameters (Id, Char) + SELECT @SP, + 'LogEvent'; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + INSERT INTO dbo.Parameters (Id, Char) + SELECT @Id, + '0.0'; + DECLARE @Types TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + DECLARE @ResourceIdInts TABLE ( + ResourceIdInt BIGINT PRIMARY KEY); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Insert', @Rows = @@rowcount; + SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1); + SET @ResourceIdInt = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255); + DELETE @Types + WHERE ResourceTypeId < @ResourceTypeId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Delete', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @Types + ORDER BY ResourceTypeId); + SET @ProcessedRows = 0; + SET @DeletedRows = 0; + SET @RowsToProcess = 1; + WHILE @RowsToProcess > 0 + BEGIN + DELETE @ResourceIdInts; + INSERT INTO @ResourceIdInts + SELECT TOP 100000 ResourceIdInt + FROM dbo.ResourceIdIntMap + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceIdInt > @ResourceIdInt + ORDER BY ResourceIdInt; + SET @RowsToProcess = @@rowcount; + SET @ProcessedRows += @RowsToProcess; + IF @RowsToProcess > 0 + SET @ResourceIdInt = (SELECT max(ResourceIdInt) + FROM @ResourceIdInts); + SET @LastProcessed = CONVERT (VARCHAR, @ResourceTypeId) + '.' + CONVERT (VARCHAR, @ResourceIdInt); + DELETE A + FROM @ResourceIdInts AS A + WHERE EXISTS (SELECT * + FROM dbo.CurrentResources AS B + WHERE B.ResourceTypeId = @ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@ResourceIdInts.Current', @Action = 'Delete', @Rows = @@rowcount, @Text = @LastProcessed; + DELETE A + FROM @ResourceIdInts AS A + WHERE EXISTS (SELECT * + FROM dbo.HistoryResources AS B + WHERE B.ResourceTypeId = @ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@ResourceIdInts.History', @Action = 'Delete', @Rows = @@rowcount, @Text = @LastProcessed; + DELETE A + FROM @ResourceIdInts AS A + WHERE EXISTS (SELECT * + FROM dbo.ResourceReferenceSearchParams AS B + WHERE B.ReferenceResourceTypeId = @ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@ResourceIdInts.Reference', @Action = 'Delete', @Rows = @@rowcount, @Text = @LastProcessed; + IF EXISTS (SELECT * + FROM @ResourceIdInts) + BEGIN + DELETE A + FROM dbo.ResourceIdIntMap AS A + WHERE A.ResourceTypeId = @ResourceTypeId + AND EXISTS (SELECT * + FROM @ResourceIdInts AS B + WHERE B.ResourceIdInt = A.ResourceIdInt); + SET @DeletedRows += @@rowcount; + END + UPDATE dbo.Parameters + SET Char = @LastProcessed + WHERE Id = @Id; + IF datediff(second, @ReportDate, getUTCdate()) > 60 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'ResourceIdIntMap', @Action = 'Select', @Rows = @ProcessedRows, @Text = @LastProcessed; + SET @ReportDate = getUTCdate(); + SET @ProcessedRows = 0; + END + END + DELETE @Types + WHERE ResourceTypeId = @ResourceTypeId; + SET @ResourceIdInt = 0; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'ResourceIdIntMap', @Action = 'Delete', @Rows = @DeletedRows, @Text = @LastProcessed; + IF @ResetAfter = 1 + DELETE dbo.Parameters + WHERE Id = @Id; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + GO CREATE OR ALTER PROCEDURE dbo.ConfigurePartitionOnResourceChanges @numberOfFuturePartitionsToAdd INT @@ -3515,7 +3643,7 @@ VALUES (@message); GO CREATE PROCEDURE dbo.MergeResources -@AffectedRows INT=0 OUTPUT, @RaiseExceptionOnConflict BIT=1, @IsResourceChangeCaptureEnabled BIT=0, @TransactionId BIGINT=NULL, @SingleTransaction BIT=1, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParms dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +@AffectedRows INT=0 OUTPUT, @RaiseExceptionOnConflict BIT=1, @IsResourceChangeCaptureEnabled BIT=0, @TransactionId BIGINT=NULL, @SingleTransaction BIT=1, @Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParms dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS SET NOCOUNT ON; DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0, @RT AS SMALLINT, @NewIdsCount AS INT, @FirstIdInt AS BIGINT; @@ -3554,6 +3682,7 @@ BEGIN TRY IsRawResourceMetaSet BIT NOT NULL, RequestMethod VARCHAR (10) NULL, SearchParamHash VARCHAR (64) NULL, + FileId BIGINT NULL, OffsetInFile INT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), UNIQUE (ResourceTypeId, ResourceIdInt, Version)); DECLARE @ReferenceSearchParamsWithIds AS TABLE ( @@ -3638,7 +3767,13 @@ BEGIN TRY INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId - FROM @Resources + FROM (SELECT ResourceTypeId, + ResourceId + FROM @ResourcesLake + UNION ALL + SELECT ResourceTypeId, + ResourceId + FROM @Resources) AS A GROUP BY ResourceTypeId, ResourceId; INSERT INTO @RTs SELECT DISTINCT ResourceTypeId @@ -3685,7 +3820,7 @@ BEGIN TRY DELETE @RTs WHERE ResourceTypeId = @RT; END - INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile) + INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile) SELECT A.ResourceTypeId, isnull(C.ResourceIdInt, B.ResourceIdInt), Version, @@ -3698,8 +3833,39 @@ BEGIN TRY RawResource, IsRawResourceMetaSet, SearchParamHash, + FileId, OffsetInFile - FROM @Resources AS A + FROM (SELECT ResourceTypeId, + ResourceId, + Version, + HasVersionToCompare, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + KeepHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END AS FileId, + OffsetInFile + FROM @ResourcesLake + UNION ALL + SELECT ResourceTypeId, + ResourceId, + Version, + HasVersionToCompare, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + KeepHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + NULL, + NULL + FROM @Resources) AS A LEFT OUTER JOIN @InsertedIds AS B ON B.ResourceTypeId = A.ResourceTypeId @@ -3957,7 +4123,7 @@ BEGIN TRY IsRawResourceMetaSet, SearchParamHash, @TransactionId, - @TransactionId, + FileId, OffsetInFile FROM @ResourcesWithIds; SET @AffectedRows += @@rowcount; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs index 0093ce5811..38762c29be 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs @@ -32,6 +32,7 @@ public static class SchemaVersionConstants public const int ExportTimeTravel = (int)SchemaVersion.V44; public const int Merge = (int)SchemaVersion.V50; public const int IncrementalImport = (int)SchemaVersion.V53; + public const int Lake = (int)SchemaVersion.V84; // It is currently used in Azure Healthcare APIs. public const int ParameterizedRemovePartitionFromResourceChangesVersion = (int)SchemaVersion.V21; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql new file mode 100644 index 0000000000..862d87d51e --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql @@ -0,0 +1,109 @@ +--DROP PROCEDURE dbo.CleanupResourceIdIntMap +GO +CREATE PROCEDURE dbo.CleanupResourceIdIntMap @ResetAfter bit = 0 +AS +set nocount on +DECLARE @SP varchar(100) = 'CleanupResourceIdIntMap' + ,@Mode varchar(100) = 'R='+isnull(convert(varchar,@ResetAfter),'NULL') + ,@st datetime = getUTCdate() + ,@Id varchar(100) = 'CleanupResourceIdIntMap.LastProcessed.TypeId.ResourceIdInt' + ,@ResourceTypeId smallint + ,@ResourceIdInt bigint + ,@RowsToProcess int + ,@ProcessedRows int = 0 + ,@DeletedRows int = 0 + ,@ReportDate datetime = getUTCdate() +DECLARE @LastProcessed varchar(100) = isnull((SELECT Char FROM dbo.Parameters WHERE Id = @Id),'0.0') + +BEGIN TRY + INSERT INTO dbo.Parameters (Id, Char) SELECT @SP, 'LogEvent' + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start' + + INSERT INTO dbo.Parameters (Id, Char) SELECT @Id, '0.0' + + DECLARE @Types TABLE (ResourceTypeId smallint PRIMARY KEY, Name varchar(100)) + DECLARE @ResourceIdInts TABLE (ResourceIdInt bigint PRIMARY KEY) + + INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@Types',@Action='Insert',@Rows=@@rowcount + + SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 1) + SET @ResourceIdInt = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 2) + + DELETE FROM @Types WHERE ResourceTypeId < @ResourceTypeId + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@Types',@Action='Delete',@Rows=@@rowcount + + WHILE EXISTS (SELECT * FROM @Types) -- Processing in ASC order + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types ORDER BY ResourceTypeId) + + SET @ProcessedRows = 0 + SET @DeletedRows = 0 + SET @RowsToProcess = 1 + WHILE @RowsToProcess > 0 + BEGIN + DELETE FROM @ResourceIdInts + + INSERT INTO @ResourceIdInts + SELECT TOP 100000 + ResourceIdInt + FROM dbo.ResourceIdIntMap + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceIdInt > @ResourceIdInt + ORDER BY + ResourceIdInt + SET @RowsToProcess = @@rowcount + SET @ProcessedRows += @RowsToProcess + + IF @RowsToProcess > 0 + SET @ResourceIdInt = (SELECT max(ResourceIdInt) FROM @ResourceIdInts) + + SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@ResourceIdInt) + + DELETE FROM A FROM @ResourceIdInts A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = @ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@ResourceIdInts.Current',@Action='Delete',@Rows=@@rowcount,@Text=@LastProcessed + + DELETE FROM A FROM @ResourceIdInts A WHERE EXISTS (SELECT * FROM dbo.HistoryResources B WHERE B.ResourceTypeId = @ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@ResourceIdInts.History',@Action='Delete',@Rows=@@rowcount,@Text=@LastProcessed + + DELETE FROM A FROM @ResourceIdInts A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = @ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@ResourceIdInts.Reference',@Action='Delete',@Rows=@@rowcount,@Text=@LastProcessed + + IF EXISTS (SELECT * FROM @ResourceIdInts) + BEGIN + DELETE FROM A FROM dbo.ResourceIdIntMap A WHERE A.ResourceTypeId = @ResourceTypeId AND EXISTS (SELECT * FROM @ResourceIdInts B WHERE B.ResourceIdInt = A.ResourceIdInt) + SET @DeletedRows += @@rowcount + END + + UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id + + IF datediff(second, @ReportDate, getUTCdate()) > 60 + BEGIN + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Select',@Rows=@ProcessedRows,@Text=@LastProcessed + SET @ReportDate = getUTCdate() + SET @ProcessedRows = 0 + END + END + + DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId + + SET @ResourceIdInt = 0 + END + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Rows=@DeletedRows,@Text=@LastProcessed + + IF @ResetAfter = 1 DELETE FROM dbo.Parameters WHERE Id = @Id + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + THROW +END CATCH +GO +--EXECUTE dbo.CleanupResourceIdIntMap 1 +--SELECT * FROM Parameters WHERE Id = 'CleanupResourceIdIntMap.LastProcessed.TypeId.ResourceIdInt' +--SELECT TOP 100 * FROM EventLog WHERE EventDate > dateadd(minute,-10,getUTCdate()) AND Process = 'CleanupResourceIdIntMap' ORDER BY EventDate DESC +--INSERT INTO Parameters (Id, Char) SELECT 'CleanupResourceIdIntMap','LogEvent' diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 69c256a897..93dd52c992 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -10,7 +10,8 @@ CREATE PROCEDURE dbo.MergeResources ,@IsResourceChangeCaptureEnabled bit = 0 ,@TransactionId bigint = NULL ,@SingleTransaction bit = 1 - ,@Resources dbo.ResourceList READONLY + ,@Resources dbo.ResourceList READONLY -- before lake code. TODO: Remove after deployment + ,@ResourcesLake dbo.ResourceListLake READONLY -- Lake code ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY ,@TokenSearchParams dbo.TokenSearchParamList READONLY @@ -63,6 +64,7 @@ BEGIN TRY ,IsRawResourceMetaSet bit NOT NULL ,RequestMethod varchar(10) NULL ,SearchParamHash varchar(64) NULL + ,FileId bigint NULL ,OffsetInFile int NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) @@ -131,7 +133,12 @@ BEGIN TRY DELETE FROM @ExistingIds -- Prepare id map for resources Start --------------------------------------------------------------------------- - INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @Resources GROUP BY ResourceTypeId, ResourceId + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId + FROM (SELECT ResourceTypeId, ResourceId FROM @ResourcesLake + UNION ALL + SELECT ResourceTypeId, ResourceId FROM @Resources -- TODO: Remove after deployment + ) A + GROUP BY ResourceTypeId, ResourceId INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds WHILE EXISTS (SELECT * FROM @RTs) @@ -168,9 +175,12 @@ BEGIN TRY END INSERT INTO @ResourcesWithIds - ( ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile ) - SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, OffsetInFile - FROM @Resources A + ( ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile + FROM (SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId = CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END, OffsetInFile FROM @ResourcesLake + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL FROM @Resources + ) A LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Action='Insert',@Target='@ResourcesWithIds',@Rows=@@rowcount,@Start=@st @@ -326,8 +336,8 @@ BEGIN TRY END INSERT INTO dbo.Resource - ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile ) - SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, @TransactionId, OffsetInFile + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, FileId, OffsetInFile FROM @ResourcesWithIds SET @AffectedRows += @@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index 90b3593491..81beff5e88 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -7,7 +7,7 @@ CREATE TABLE dbo.ReferenceSearchParam ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL ,ReferenceResourceTypeId smallint NULL ,ReferenceResourceIdInt bigint NOT NULL - ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL ) GO DROP TABLE dbo.ReferenceSearchParam @@ -41,7 +41,7 @@ CREATE TABLE dbo.StringReferenceSearchParams ,ResourceSurrogateId bigint NOT NULL ,SearchParamId smallint NOT NULL ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL - ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL ,IsResourceRef bit NOT NULL CONSTRAINT DF_StringReferenceSearchParams_IsResourceRef DEFAULT 0, CONSTRAINT CH_StringReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 0) ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ReferenceSearchParamList.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ReferenceSearchParamList.sql index 796604196e..2026574ad4 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ReferenceSearchParamList.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ReferenceSearchParamList.sql @@ -7,7 +7,7 @@ CREATE TYPE dbo.ReferenceSearchParamList AS TABLE ,SearchParamId smallint NOT NULL ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL ,ReferenceResourceTypeId smallint NULL - ,ReferenceResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL ,ReferenceResourceVersion int NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql index d79569064e..d27e6dd3f0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceList.sql @@ -10,11 +10,10 @@ CREATE TYPE dbo.ResourceList AS TABLE ,IsDeleted bit NOT NULL ,IsHistory bit NOT NULL ,KeepHistory bit NOT NULL - ,RawResource varbinary(max) NULL + ,RawResource varbinary(max) NOT NULL ,IsRawResourceMetaSet bit NOT NULL ,RequestMethod varchar(10) NULL ,SearchParamHash varchar(64) NULL - ,OffsetInFile int NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) ,UNIQUE (ResourceTypeId, ResourceId, Version) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql new file mode 100644 index 0000000000..9ce399c2f7 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql @@ -0,0 +1,22 @@ +--DROP TYPE dbo.ResourceListLake +GO +CREATE TYPE dbo.ResourceListLake AS TABLE +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,Version int NOT NULL + ,HasVersionToCompare bit NOT NULL -- in case of multiple versions per resource indicates that row contains (existing version + 1) value + ,IsDeleted bit NOT NULL + ,IsHistory bit NOT NULL + ,KeepHistory bit NOT NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,RequestMethod varchar(10) NULL + ,SearchParamHash varchar(64) NULL + ,OffsetInFile int NULL + + PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) + ,UNIQUE (ResourceTypeId, ResourceId, Version) +) +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index 6575c79b9b..4d330b250c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -30,6 +30,7 @@ using Microsoft.Health.Fhir.Core.Features.Persistence; using Microsoft.Health.Fhir.Core.Features.Persistence.Orchestration; using Microsoft.Health.Fhir.Core.Models; +using Microsoft.Health.Fhir.SqlServer.Features.Schema; using Microsoft.Health.Fhir.SqlServer.Features.Schema.Model; using Microsoft.Health.Fhir.SqlServer.Features.Storage.TvpRowGeneration; using Microsoft.Health.Fhir.SqlServer.Features.Storage.TvpRowGeneration.Merge; @@ -766,7 +767,15 @@ internal async Task MergeResourcesWrapperAsync(long transactionId, bool singleTr await PutRawResourcesIntoAdls(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource } - new ResourceListTableValuedParameterDefinition("@Resources").AddParameter(cmd.Parameters, new ResourceListRowGenerator(_model, _compressedRawResourceConverter).GenerateRows(mergeWrappers)); + if (_schemaInformation.Current >= SchemaVersionConstants.Lake) + { + new ResourceListLakeTableValuedParameterDefinition("@ResourcesLake").AddParameter(cmd.Parameters, new ResourceListLakeRowGenerator(_model, _compressedRawResourceConverter).GenerateRows(mergeWrappers)); + } + else + { + new ResourceListTableValuedParameterDefinition("@Resources").AddParameter(cmd.Parameters, new ResourceListRowGenerator(_model, _compressedRawResourceConverter).GenerateRows(mergeWrappers)); + } + new ResourceWriteClaimListTableValuedParameterDefinition("@ResourceWriteClaims").AddParameter(cmd.Parameters, new ResourceWriteClaimListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); new ReferenceSearchParamListTableValuedParameterDefinition("@ReferenceSearchParams").AddParameter(cmd.Parameters, new ReferenceSearchParamListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); new TokenSearchParamListTableValuedParameterDefinition("@TokenSearchParams").AddParameter(cmd.Parameters, new TokenSearchParamListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs new file mode 100644 index 0000000000..2d0cf32cec --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs @@ -0,0 +1,42 @@ +// ------------------------------------------------------------------------------------------------- +// Copyright (c) Microsoft Corporation. All rights reserved. +// Licensed under the MIT License (MIT). See LICENSE in the repo root for license information. +// ------------------------------------------------------------------------------------------------- + +using System.Collections.Generic; +using EnsureThat; +using Microsoft.Health.Fhir.Core.Features.Operations; +using Microsoft.Health.Fhir.SqlServer.Features.Schema.Model; +using Microsoft.Health.Fhir.SqlServer.Features.Storage.TvpRowGeneration.Merge; +using Microsoft.Health.SqlServer.Features.Schema.Model; +using Microsoft.IO; + +namespace Microsoft.Health.Fhir.SqlServer.Features.Storage.TvpRowGeneration +{ + internal class ResourceListLakeRowGenerator : ITableValuedParameterRowGenerator, ResourceListLakeRow> + { + private readonly ISqlServerFhirModel _model; + private readonly ICompressedRawResourceConverter _compressedRawResourceConverter; + private readonly RecyclableMemoryStreamManager _memoryStreamManager; + + public ResourceListLakeRowGenerator(ISqlServerFhirModel model, ICompressedRawResourceConverter compressedRawResourceConverter) + { + _model = EnsureArg.IsNotNull(model, nameof(model)); + _compressedRawResourceConverter = EnsureArg.IsNotNull(compressedRawResourceConverter, nameof(compressedRawResourceConverter)); + _memoryStreamManager = new RecyclableMemoryStreamManager(); + } + + public IEnumerable GenerateRows(IReadOnlyList mergeWrappers) + { + foreach (var merge in mergeWrappers) + { + var wrapper = merge.ResourceWrapper; + using var stream = new RecyclableMemoryStream(_memoryStreamManager, tag: nameof(ResourceListRowGenerator)); + _compressedRawResourceConverter.WriteCompressedRawResource(stream, wrapper.RawResource.Data); + stream.Seek(0, 0); + + yield return new ResourceListLakeRow(_model.GetResourceTypeId(wrapper.ResourceTypeName), merge.ResourceWrapper.ResourceSurrogateId, wrapper.ResourceId, int.Parse(wrapper.Version), merge.HasVersionToCompare, wrapper.IsDeleted, wrapper.IsHistory, merge.KeepHistory, merge.OffsetInFile.HasValue ? null : stream, wrapper.RawResource.IsMetaSet, wrapper.Request?.Method, wrapper.SearchParameterHash, merge.OffsetInFile); + } + } + } +} diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs index fb2fb796a2..1d33ac04c2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs @@ -35,7 +35,7 @@ public IEnumerable GenerateRows(IReadOnlyList Date: Wed, 20 Nov 2024 15:50:29 -0800 Subject: [PATCH 029/111] no lake on list --- .../Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs index 1d33ac04c2..46480a7507 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs @@ -35,7 +35,7 @@ public IEnumerable GenerateRows(IReadOnlyList Date: Wed, 20 Nov 2024 15:51:36 -0800 Subject: [PATCH 030/111] no extra lines --- .../TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs | 1 - .../Storage/TvpRowGeneration/Merge/ResourceListRowGenerator.cs | 1 - 2 files changed, 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs index 2d0cf32cec..25ad1241d5 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs @@ -34,7 +34,6 @@ public IEnumerable GenerateRows(IReadOnlyList GenerateRows(IReadOnlyList Date: Wed, 20 Nov 2024 16:50:06 -0800 Subject: [PATCH 031/111] small cleanup --- .../Features/Schema/Sql/Sprocs/MergeResources.sql | 7 ++----- 1 file changed, 2 insertions(+), 5 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 93dd52c992..5681678ab0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -211,7 +211,6 @@ END CATCH --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Text='ResourceIdIntMap populated' BEGIN TRY - DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) DECLARE @ResourceInfos AS TABLE @@ -270,7 +269,7 @@ BEGIN TRY SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds WHERE HasVersionToCompare = 1) A LEFT OUTER JOIN dbo.CurrentResources B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. - ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.IsHistory = 0 + ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <= PreviousVersion) @@ -301,9 +300,7 @@ BEGIN TRY DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount - DELETE FROM dbo.ResourceReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) - SET @AffectedRows += @@rowcount - DELETE FROM dbo.StringReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount From 90132fb03c330fe809a02f52328fb47fad065e7c Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 21 Nov 2024 13:48:35 -0800 Subject: [PATCH 032/111] 84 in sync --- .../Features/Schema/Migrations/84.sql | 9 +-------- 1 file changed, 1 insertion(+), 8 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 4038f446ca..333c0f60f6 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -3968,7 +3968,6 @@ BEGIN TRY dbo.CurrentResources AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt - AND B.IsHistory = 0 OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * @@ -4020,13 +4019,7 @@ BEGIN TRY FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; - DELETE dbo.ResourceReferenceSearchParams - WHERE EXISTS (SELECT * - FROM @PreviousSurrogateIds - WHERE TypeId = ResourceTypeId - AND SurrogateId = ResourceSurrogateId); - SET @AffectedRows += @@rowcount; - DELETE dbo.StringReferenceSearchParams + DELETE dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId From 77d4950318844aab6680a71b706e5f81edbaef6d Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 22 Nov 2024 14:58:02 -0800 Subject: [PATCH 033/111] diff --- .../Features/Schema/Migrations/84.diff.sql | 1830 ++++++++++++++++- .../Features/Schema/Migrations/84.sql | 57 +- .../Features/Schema/SchemaVersionConstants.cs | 2 +- .../Schema/Sql/Sprocs/GetResourceVersions.sql | 2 +- .../Schema/Sql/Sprocs/GetResources.sql | 26 +- .../QueryGenerators/SqlQueryGenerator.cs | 8 +- .../Features/Search/SqlServerSearchService.cs | 4 +- .../Storage/SqlServerFhirDataStore.cs | 12 +- .../Features/Storage/SqlStoreClient.cs | 8 +- 9 files changed, 1880 insertions(+), 69 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 0e3570f066..1386c1f511 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -1 +1,1829 @@ ---SET TRANSACTION ISOLATION LEVEL READ COMMITTED -- Not sure that it matters, but to gurantee that SQL versioning is not used ---- Disable defrag --UPDATE Parameters SET Number = 0 WHERE Id = 'DefragWatchdog.IsEnabled' --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Update',@Rows=@@rowcount,@Text='disable defrag' --GO --IF (SELECT sum(reserved_page_count*8.0/1024/1024) FROM sys.dm_db_partition_stats) > 2500 -- skip for large databases --BEGIN -- INSERT INTO dbo.Parameters (Id, Number) SELECT 'SkipHistorySeparation', 1 -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Warn',@Target='Parameters',@Action='Insert',@Rows=@@rowcount,@Text='SkipHistorySeparation' --END --GO --ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalStartId bigint = NULL, @GlobalEndId bigint = NULL --AS --set nocount on --DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' -- ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') -- +' S='+isnull(convert(varchar,@StartId),'NULL') -- +' E='+isnull(convert(varchar,@EndId),'NULL') -- +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') -- Could this just be a boolean for if historical records should be returned? GlobalEndId should equal EndId in all cases I can think of. -- ,@st datetime = getUTCdate() -- ,@DummyTop bigint = 9223372036854775807 --BEGIN TRY -- DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) -- DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) -- IF @GlobalEndId IS NOT NULL -- snapshot view -- BEGIN -- INSERT INTO @ResourceIds -- SELECT DISTINCT ResourceId -- FROM dbo.Resource -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId BETWEEN @StartId AND @EndId -- AND IsHistory = 1 -- AND IsDeleted = 0 -- OPTION (MAXDOP 1) -- IF @@rowcount > 0 -- INSERT INTO @SurrogateIds -- SELECT ResourceSurrogateId -- FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) -- FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) -- w/o hint access to Resource table is inefficient when many versions are present. Hint is ignored if Resource is a view. -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) -- AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId -- ) A -- WHERE RowId = 1 -- AND ResourceSurrogateId BETWEEN @StartId AND @EndId -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- END -- SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource -- FROM dbo.Resource -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId BETWEEN @StartId AND @EndId -- AND IsHistory = 0 -- AND IsDeleted = 0 -- UNION ALL -- SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource -- FROM @SurrogateIds -- JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId -- WHERE IsHistory = 1 -- AND IsDeleted = 0 -- OPTION (MAXDOP 1) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; -- THROW --END CATCH --GO --ALTER PROCEDURE dbo.DequeueJob @QueueType tinyint, @Worker varchar(100), @HeartbeatTimeoutSec int, @InputJobId bigint = NULL, @CheckTimeoutJobs bit = 0 --AS --set nocount on --DECLARE @SP varchar(100) = 'DequeueJob' -- ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') -- +' H='+isnull(convert(varchar,@HeartbeatTimeoutSec),'NULL') -- +' W='+isnull(@Worker,'NULL') -- +' IJ='+isnull(convert(varchar,@InputJobId),'NULL') -- +' T='+isnull(convert(varchar,@CheckTimeoutJobs),'NULL') -- ,@Rows int = 0 -- ,@st datetime = getUTCdate() -- ,@JobId bigint -- ,@msg varchar(100) -- ,@Lock varchar(100) -- ,@PartitionId tinyint -- ,@MaxPartitions tinyint = 16 -- !!! hardcoded -- ,@LookedAtPartitions tinyint = 0 --BEGIN TRY -- IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'DequeueJobStop' AND Number = 1) -- BEGIN -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=0,@Text='Skipped' -- RETURN -- END -- IF @InputJobId IS NULL -- SET @PartitionId = @MaxPartitions * rand() -- ELSE -- SET @PartitionId = @InputJobId % 16 -- SET TRANSACTION ISOLATION LEVEL READ COMMITTED -- WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions AND @CheckTimeoutJobs = 0 -- BEGIN -- SET @Lock = 'DequeueJob_'+convert(varchar,@QueueType)+'_'+convert(varchar,@PartitionId) -- BEGIN TRANSACTION -- EXECUTE sp_getapplock @Lock, 'Exclusive' -- UPDATE T -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = 1 -- running -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = T.JobId -- FROM dbo.JobQueue T WITH (PAGLOCK) -- JOIN (SELECT TOP 1 -- JobId -- FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) -- WHERE QueueType = @QueueType -- AND PartitionId = @PartitionId -- AND Status = 0 -- ORDER BY -- Priority -- ,JobId -- ) S -- ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId -- SET @Rows += @@rowcount -- COMMIT TRANSACTION -- IF @JobId IS NULL -- BEGIN -- SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END -- SET @LookedAtPartitions = @LookedAtPartitions + 1 -- END -- END -- -- Do timed out items. -- SET @LookedAtPartitions = 0 -- WHILE @InputJobId IS NULL AND @JobId IS NULL AND @LookedAtPartitions < @MaxPartitions -- BEGIN -- SET @Lock = 'DequeueStoreCopyWorkUnit_'+convert(varchar, @PartitionId) -- BEGIN TRANSACTION -- EXECUTE sp_getapplock @Lock, 'Exclusive' -- UPDATE T -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = CASE WHEN CancelRequested = 0 THEN 1 ELSE 4 END -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = CASE WHEN CancelRequested = 0 THEN T.JobId END -- ,Info = convert(varchar(1000),isnull(Info,'')+' Prev: Worker='+Worker+' Start='+convert(varchar,StartDate,121)) -- FROM dbo.JobQueue T WITH (PAGLOCK) -- JOIN (SELECT TOP 1 -- JobId -- FROM dbo.JobQueue WITH (INDEX = IX_QueueType_PartitionId_Status_Priority) -- WHERE QueueType = @QueueType -- AND PartitionId = @PartitionId -- AND Status = 1 -- AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec -- ORDER BY -- Priority -- ,JobId -- ) S -- ON QueueType = @QueueType AND PartitionId = @PartitionId AND T.JobId = S.JobId -- SET @Rows += @@rowcount -- COMMIT TRANSACTION -- IF @JobId IS NULL -- BEGIN -- SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END -- SET @LookedAtPartitions = @LookedAtPartitions + 1 -- END -- END -- IF @InputJobId IS NOT NULL -- BEGIN -- UPDATE dbo.JobQueue WITH (PAGLOCK) -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = 1 -- running -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = JobId -- WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 0 AND JobId = @InputJobId -- SET @Rows += @@rowcount -- IF @JobId IS NULL -- BEGIN -- UPDATE dbo.JobQueue WITH (PAGLOCK) -- SET StartDate = getUTCdate() -- ,HeartbeatDate = getUTCdate() -- ,Worker = @Worker -- ,Status = 1 -- running -- ,Version = datediff_big(millisecond,'0001-01-01',getUTCdate()) -- ,@JobId = JobId -- WHERE QueueType = @QueueType AND PartitionId = @PartitionId AND Status = 1 AND JobId = @InputJobId -- AND datediff(second,HeartbeatDate,getUTCdate()) > @HeartbeatTimeoutSec -- SET @Rows += @@rowcount -- END -- END -- IF @JobId IS NOT NULL -- EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobId = @JobId -- SET @msg = 'J='+isnull(convert(varchar,@JobId),'NULL')+' P='+convert(varchar,@PartitionId) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows,@Text=@msg --END TRY --BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='DequeueJob',@Action='Alter' --GO --ALTER PROCEDURE dbo.GetActiveJobs @QueueType tinyint, @GroupId bigint = NULL --AS --set nocount on --DECLARE @SP varchar(100) = 'GetActiveJobs' -- ,@Mode varchar(100) = 'Q='+isnull(convert(varchar,@QueueType),'NULL') -- +' G='+isnull(convert(varchar,@GroupId),'NULL') -- ,@st datetime = getUTCdate() -- ,@JobIds BigintList -- ,@PartitionId tinyint -- ,@MaxPartitions tinyint = 16 -- !!! hardcoded -- ,@LookedAtPartitions tinyint = 0 -- ,@Rows int = 0 --BEGIN TRY -- SET @PartitionId = @MaxPartitions * rand() -- WHILE @LookedAtPartitions < @MaxPartitions -- BEGIN -- IF @GroupId IS NULL -- INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND Status IN (0,1) -- ELSE -- INSERT INTO @JobIds SELECT JobId FROM dbo.JobQueue WHERE PartitionId = @PartitionId AND QueueType = @QueueType AND GroupId = @GroupId AND Status IN (0,1) -- SET @Rows += @@rowcount -- SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END -- SET @LookedAtPartitions += 1 -- END -- IF @Rows > 0 -- EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='65.diff.sql',@Status='Warn',@Target='GetActiveJobs',@Action='Alter' --GO --INSERT INTO dbo.Parameters (Id, Char) SELECT 'HistorySeparation', 'LogEvent' --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Start' --GO --ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY --AS --set nocount on --DECLARE @st datetime = getUTCdate() -- ,@SP varchar(100) = 'GetResources' -- ,@InputRows int -- ,@DummyTop bigint = 9223372036854775807 -- ,@NotNullVersionExists bit -- ,@NullVersionExists bit -- ,@MinRT smallint -- ,@MaxRT smallint --SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys --DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) --BEGIN TRY -- IF @NotNullVersionExists = 1 -- IF @NullVersionExists = 0 -- SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- ELSE -- SELECT * -- FROM (SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version -- UNION ALL -- SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId -- WHERE IsHistory = 0 -- ) A -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- ELSE -- SELECT B.ResourceTypeId -- ,B.ResourceId -- ,ResourceSurrogateId -- ,B.Version -- ,IsDeleted -- ,IsHistory -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A -- JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId -- WHERE IsHistory = 0 -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='GetResources',@Action='Alter' --GO --ALTER PROCEDURE dbo.MergeResources ---- This stored procedure can be used for: ---- 1. Ordinary put with single version per resource in input ---- 2. Put with history preservation (multiple input versions per resource) ---- 3. Copy from one gen2 store to another with ResourceSurrogateId preserved. -- @AffectedRows int = 0 OUT -- ,@RaiseExceptionOnConflict bit = 1 -- ,@IsResourceChangeCaptureEnabled bit = 0 -- ,@TransactionId bigint = NULL -- ,@SingleTransaction bit = 1 -- ,@Resources dbo.ResourceList READONLY -- ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY -- ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY -- ,@TokenSearchParams dbo.TokenSearchParamList READONLY -- ,@TokenTexts dbo.TokenTextList READONLY -- ,@StringSearchParams dbo.StringSearchParamList READONLY -- ,@UriSearchParams dbo.UriSearchParamList READONLY -- ,@NumberSearchParams dbo.NumberSearchParamList READONLY -- ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY -- ,@DateTimeSearchParms dbo.DateTimeSearchParamList READONLY -- ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY -- ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY -- ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY -- ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY -- ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY -- ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY --AS --set nocount on --DECLARE @st datetime = getUTCdate() -- ,@SP varchar(100) = object_name(@@procid) -- ,@DummyTop bigint = 9223372036854775807 -- ,@InitialTranCount int = @@trancount -- ,@IsRetry bit = 0 --DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') --SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') --SET @AffectedRows = 0 --BEGIN TRY -- DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) -- DECLARE @ResourceInfos AS TABLE -- ( -- ResourceTypeId smallint NOT NULL -- ,SurrogateId bigint NOT NULL -- ,Version int NOT NULL -- ,KeepHistory bit NOT NULL -- ,PreviousVersion int NULL -- ,PreviousSurrogateId bigint NULL -- PRIMARY KEY (ResourceTypeId, SurrogateId) -- ) -- DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) -- IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 -- SET @SingleTransaction = 1 -- SET @Mode += ' ST='+convert(varchar,@SingleTransaction) -- -- perform retry check in transaction to hold locks -- IF @InitialTranCount = 0 -- BEGIN -- IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them -- FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE B.IsHistory = 0 -- ) -- BEGIN -- BEGIN TRANSACTION -- INSERT INTO @Existing -- ( ResourceTypeId, SurrogateId ) -- SELECT B.ResourceTypeId, B.ResourceSurrogateId -- FROM (SELECT TOP (@DummyTop) * FROM @Resources) A -- JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE B.IsHistory = 0 -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- IF @@rowcount > 0 SET @IsRetry = 1 -- IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction -- END -- END -- SET @Mode += ' R='+convert(varchar,@IsRetry) -- IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION -- IF @IsRetry = 0 -- BEGIN -- INSERT INTO @ResourceInfos -- ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) -- SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId -- FROM (SELECT TOP (@DummyTop) * FROM @Resources WHERE HasVersionToCompare = 1) A -- LEFT OUTER JOIN dbo.Resource B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. -- ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <> PreviousVersion + 1) -- THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 -- INSERT INTO @PreviousSurrogateIds -- SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory -- FROM @ResourceInfos -- WHERE PreviousSurrogateId IS NOT NULL -- IF @@rowcount > 0 -- BEGIN -- UPDATE dbo.Resource -- SET IsHistory = 1 -- WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) -- SET @AffectedRows += @@rowcount -- IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) -- UPDATE dbo.Resource -- SET IsHistory = 1 -- ,RawResource = 0xF -- "invisible" value -- ,SearchParamHash = NULL -- ,HistoryTransactionId = @TransactionId -- WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) -- ELSE -- DELETE FROM dbo.Resource WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenText WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.StringSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.UriSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.NumberSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.QuantitySearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.DateTimeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.ReferenceTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenDateTimeCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenQuantityCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenStringCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) -- SET @AffectedRows += @@rowcount -- --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' -- END -- INSERT INTO dbo.Resource -- ( ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId ) -- SELECT ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId -- FROM @Resources -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ResourceWriteClaim -- ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) -- SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue -- FROM @ResourceWriteClaims -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion -- FROM @ReferenceSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow -- FROM @TokenSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenText -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text -- FROM @TokenTexts -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.StringSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax -- FROM @StringSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.UriSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri -- FROM @UriSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.NumberSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue -- FROM @NumberSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.QuantitySearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue -- FROM @QuantitySearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.DateTimeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax -- FROM @DateTimeSearchParms -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 -- FROM @ReferenceTokenCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 -- FROM @TokenTokenCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenDateTimeCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 -- FROM @TokenDateTimeCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenQuantityCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 -- FROM @TokenQuantityCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenStringCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 -- FROM @TokenStringCompositeSearchParams -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenNumberNumberCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange -- FROM @TokenNumberNumberCompositeSearchParams -- SET @AffectedRows += @@rowcount -- END -- @IsRetry = 0 -- ELSE -- BEGIN -- @IsRetry = 1 -- INSERT INTO dbo.ResourceWriteClaim -- ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) -- SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue -- FROM (SELECT TOP (@DummyTop) * FROM @ResourceWriteClaims) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.ResourceWriteClaim C WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion -- FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.ReferenceSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow -- FROM (SELECT TOP (@DummyTop) * FROM @TokenSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenText -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text -- FROM (SELECT TOP (@DummyTop) * FROM @TokenTexts) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.StringSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax -- FROM (SELECT TOP (@DummyTop) * FROM @StringSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenText C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.UriSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri -- FROM (SELECT TOP (@DummyTop) * FROM @UriSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.UriSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.NumberSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue -- FROM (SELECT TOP (@DummyTop) * FROM @NumberSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.NumberSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.QuantitySearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue -- FROM (SELECT TOP (@DummyTop) * FROM @QuantitySearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.QuantitySearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.DateTimeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax -- FROM (SELECT TOP (@DummyTop) * FROM @DateTimeSearchParms) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.ReferenceTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 -- FROM (SELECT TOP (@DummyTop) * FROM @ReferenceTokenCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.DateTimeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenTokenCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenTokenCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenDateTimeCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenDateTimeCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenDateTimeCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenQuantityCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenQuantityCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenQuantityCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenStringCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 -- FROM (SELECT TOP (@DummyTop) * FROM @TokenStringCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenStringCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- INSERT INTO dbo.TokenNumberNumberCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange -- FROM (SELECT TOP (@DummyTop) * FROM @TokenNumberNumberCompositeSearchParams) A -- WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) -- AND NOT EXISTS (SELECT * FROM dbo.TokenNumberNumberCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- SET @AffectedRows += @@rowcount -- END -- IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. -- EXECUTE dbo.CaptureResourceIdsForChanges @Resources -- IF @TransactionId IS NOT NULL -- EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId -- IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows --END TRY --BEGIN CATCH -- IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource''%' OR error_message() LIKE '%''dbo.ResourceCurrent''%' OR error_message() LIKE '%''dbo.ResourceHistory''%') -- handles old and separated tables -- THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; -- ELSE -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='MergeResources',@Action='Alter' --GO --ALTER PROCEDURE dbo.UpdateResourceSearchParams -- @FailedResources int = 0 OUT -- ,@Resources dbo.ResourceList READONLY -- ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY -- ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY -- ,@TokenSearchParams dbo.TokenSearchParamList READONLY -- ,@TokenTexts dbo.TokenTextList READONLY -- ,@StringSearchParams dbo.StringSearchParamList READONLY -- ,@UriSearchParams dbo.UriSearchParamList READONLY -- ,@NumberSearchParams dbo.NumberSearchParamList READONLY -- ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY -- ,@DateTimeSearchParams dbo.DateTimeSearchParamList READONLY -- ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY -- ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY -- ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY -- ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY -- ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY -- ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY --AS --set nocount on --DECLARE @st datetime = getUTCdate() -- ,@SP varchar(100) = object_name(@@procid) -- ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') -- ,@Rows int --BEGIN TRY -- DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) -- BEGIN TRANSACTION -- -- Update the search parameter hash value in the main resource table -- -- Avoid join to enable update via view -- UPDATE A -- SET SearchParamHash = (SELECT SearchParamHash FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- FROM dbo.Resource A -- WHERE IsHistory = 0 -- AND EXISTS (SELECT * FROM @Resources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- SET @Rows = @@rowcount -- -- First, delete all the search params of the resources to reindex. -- DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.ReferenceSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- DELETE FROM B FROM @Ids A JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- -- Next, insert all the new search params. -- INSERT INTO dbo.ResourceWriteClaim -- ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) -- SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue -- FROM @ResourceWriteClaims -- INSERT INTO dbo.ReferenceSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion -- FROM @ReferenceSearchParams -- INSERT INTO dbo.TokenSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow -- FROM @TokenSearchParams -- INSERT INTO dbo.TokenText -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text -- FROM @TokenTexts -- INSERT INTO dbo.StringSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax -- FROM @StringSearchParams -- INSERT INTO dbo.UriSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri -- FROM @UriSearchParams -- INSERT INTO dbo.NumberSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue -- FROM @NumberSearchParams -- INSERT INTO dbo.QuantitySearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue -- FROM @QuantitySearchParams -- INSERT INTO dbo.DateTimeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax -- FROM @DateTimeSearchParams -- INSERT INTO dbo.ReferenceTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 -- FROM @ReferenceTokenCompositeSearchParams -- INSERT INTO dbo.TokenTokenCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 -- FROM @TokenTokenCompositeSearchParams -- INSERT INTO dbo.TokenDateTimeCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 -- FROM @TokenDateTimeCompositeSearchParams -- INSERT INTO dbo.TokenQuantityCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 -- FROM @TokenQuantityCompositeSearchParams -- INSERT INTO dbo.TokenStringCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 -- FROM @TokenStringCompositeSearchParams -- INSERT INTO dbo.TokenNumberNumberCompositeSearchParam -- ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) -- SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange -- FROM @TokenNumberNumberCompositeSearchParams -- COMMIT TRANSACTION -- SET @FailedResources = (SELECT count(*) FROM @Resources) - @Rows -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows --END TRY --BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='UpdateResourceSearchParams',@Action='Alter' --GO --ALTER PROCEDURE dbo.DisableIndexes --WITH EXECUTE AS 'dbo' --AS --set nocount on --DECLARE @SP varchar(100) = 'DisableIndexes' -- ,@Mode varchar(200) = '' -- ,@st datetime = getUTCdate() -- ,@Tbl varchar(100) -- ,@Ind varchar(200) -- ,@Txt varchar(4000) --BEGIN TRY -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start' -- DECLARE @Tables TABLE (Tbl varchar(100) PRIMARY KEY, Supported bit) -- INSERT INTO @Tables EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0 -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Tables',@Action='Insert',@Rows=@@rowcount -- DECLARE @Indexes TABLE (Tbl varchar(100), Ind varchar(200), TblId int, IndId int PRIMARY KEY (Tbl, Ind)) -- INSERT INTO @Indexes -- SELECT Tbl -- ,I.Name -- ,TblId -- ,I.index_id -- FROM (SELECT TblId = object_id(Tbl), Tbl FROM @Tables) O -- JOIN sys.indexes I ON I.object_id = TblId -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Insert',@Rows=@@rowcount -- INSERT INTO dbo.IndexProperties -- ( TableName, IndexName, PropertyName, PropertyValue ) -- SELECT Tbl, Ind, 'DATA_COMPRESSION', data_comp -- FROM (SELECT Tbl -- ,Ind -- ,data_comp = isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END FROM sys.partitions WHERE object_id = TblId AND index_id = IndId),'NONE') -- FROM @Indexes -- ) A -- WHERE NOT EXISTS (SELECT * FROM dbo.IndexProperties WHERE TableName = Tbl AND IndexName = Ind) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='IndexProperties',@Action='Insert',@Rows=@@rowcount -- DELETE FROM @Indexes WHERE Tbl IN ('Resource','ResourceCurrent','ResourceHistory') OR IndId = 1 -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Delete',@Rows=@@rowcount -- WHILE EXISTS (SELECT * FROM @Indexes) -- BEGIN -- SELECT TOP 1 @Tbl = Tbl, @Ind = Ind FROM @Indexes -- SET @Txt = 'ALTER INDEX '+@Ind+' ON dbo.'+@Tbl+' DISABLE' -- EXECUTE(@Txt) -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target=@Ind,@Action='Disable',@Text=@Txt -- DELETE FROM @Indexes WHERE Tbl = @Tbl AND Ind = @Ind -- END -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st --END TRY --BEGIN CATCH -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; -- THROW --END CATCH --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='DisableIndexes',@Action='Alter' --GO --IF object_id('dbo.ResourceCurrent') IS NULL --BEGIN -- BEGIN TRY -- BEGIN TRANSACTION -- CREATE TABLE dbo.ResourceCurrent -- ( -- ResourceTypeId smallint NOT NULL -- ,ResourceSurrogateId bigint NOT NULL -- ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL -- ,Version int NOT NULL -- ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) -- ,IsDeleted bit NOT NULL -- ,RequestMethod varchar(10) NULL -- ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceCurrent_RawResource_Length CHECK (RawResource > 0x0) -- ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceCurrent_IsRawResourceMetaSet DEFAULT 0 -- ,SearchParamHash varchar(64) NULL -- ,TransactionId bigint NULL -- used for main CRUD operation -- CONSTRAINT PKC_ResourceCurrent_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ,CONSTRAINT U_ResourceCurrent_ResourceTypeId_ResourceId UNIQUE (ResourceTypeId, ResourceId) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ) -- ALTER TABLE dbo.ResourceCurrent SET ( LOCK_ESCALATION = AUTO ) -- CREATE UNIQUE INDEX IXU_ResourceTypeId_ResourceSurrogateId_WHERE_IsHistory_0_IsDeleted_0 ON dbo.ResourceCurrent (ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 AND IsDeleted = 0 ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceCurrent (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceCurrent',@Action='Create' -- CREATE TABLE dbo.ResourceHistory -- ( -- ResourceTypeId smallint NOT NULL -- ,ResourceSurrogateId bigint NOT NULL -- ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL -- ,Version int NOT NULL -- ,IsHistory bit NOT NULL CONSTRAINT DF_ResourceHistory_IsHistory DEFAULT 1, CONSTRAINT CH_ResourceHistory_IsHistory CHECK (IsHistory = 1) -- ,IsDeleted bit NOT NULL -- ,RequestMethod varchar(10) NULL -- ,RawResource varbinary(max) NOT NULL CONSTRAINT CH_ResourceHistory_RawResource_Length CHECK (RawResource > 0x0) -- ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_ResourceHistory_IsRawResourceMetaSet DEFAULT 0 -- ,SearchParamHash varchar(64) NULL -- ,TransactionId bigint NULL -- used for main CRUD operation -- ,HistoryTransactionId bigint NULL -- used by CRUD operation that moved resource version in invisible state -- CONSTRAINT PKC_ResourceHistory_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ,CONSTRAINT U_ResourceHistory_ResourceTypeId_ResourceId_Version UNIQUE (ResourceTypeId, ResourceId, Version) ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- ) -- ALTER TABLE dbo.ResourceHistory SET ( LOCK_ESCALATION = AUTO ) -- CREATE INDEX IX_ResourceTypeId_TransactionId_WHERE_TransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- CREATE INDEX IX_ResourceTypeId_HistoryTransactionId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.ResourceHistory (ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL ON PartitionScheme_ResourceTypeId (ResourceTypeId) -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceHistory',@Action='Create' -- COMMIT TRANSACTION -- END TRY -- BEGIN CATCH -- ROLLBACK TRANSACTION -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; -- THROW -- END CATCH --END --GO --IF EXISTS (SELECT * FROM sys.objects WHERE object_id = object_id('dbo.Resource') AND type = 'u') -- AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'SkipHistorySeparation' AND Number = 1) --BEGIN -- --CREATE TRIGGER dbo.ResourceIns -- EXECUTE(' --CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource AFTER INSERT --AS --BEGIN -- INSERT INTO dbo.ResourceCurrent -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM Inserted -- WHERE IsHistory = 0 -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' -- --CREATE TRIGGER dbo.ResourceUpd -- EXECUTE(' --CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource AFTER UPDATE --AS --BEGIN -- UPDATE B -- SET SearchParamHash = A.SearchParamHash -- this is the only update we support -- FROM Inserted A -- JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE A.IsHistory = 0 -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' -- --CREATE TRIGGER dbo.ResourceDel -- EXECUTE(' --CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource AFTER DELETE --AS --BEGIN -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) -- DELETE FROM A -- FROM dbo.ResourceHistory A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' -- DECLARE @Types TABLE (ResourceTypeId smallint PRIMARY KEY, Name varchar(100)) -- DECLARE @MaxSurrogateId bigint = 0 -- ,@ResourceTypeId smallint -- IF NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') -- DELETE FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId' -- BEGIN -- DECLARE @MaxSurrogateIdTmp bigint -- INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes -- WHILE EXISTS (SELECT * FROM @Types) -- BEGIN -- SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types) -- SET @MaxSurrogateIdTmp = (SELECT max(ResourceSurrogateId) FROM Resource WHERE ResourceTypeId = @ResourceTypeId) -- IF @MaxSurrogateIdTmp > @MaxSurrogateId SET @MaxSurrogateId = @MaxSurrogateIdTmp -- DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId -- END -- INSERT INTO dbo.Parameters (Id, Bigint) SELECT 'HistorySeparation.MaxSurrogateId', @MaxSurrogateId -- END -- SET @MaxSurrogateId = (SELECT Bigint FROM dbo.Parameters WHERE Id = 'HistorySeparation.MaxSurrogateId') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='@MaxSurrogateId',@Action='Select',@Text=@MaxSurrogateId -- -- Copy start ---------------------------------------------------------------------------------------------------------- -- DECLARE @Process varchar(100) = 'HistorySeparation.CopyResources' -- ,@Id varchar(100) = 'HistorySeparation.CopyResources.LastProcessed.TypeId.SurrogateId' -- ,@SurrogateId bigint -- ,@RowsToProcess int -- ,@ProcessedResources int -- ,@ReportDate datetime = getUTCdate() -- ,@DummyTop bigint = 9223372036854775807 -- ,@Rows int -- ,@CurrentMaxSurrogateId bigint -- ,@LastProcessed varchar(100) -- ,@st datetime -- BEGIN TRY -- INSERT INTO dbo.Parameters (Id, Char) SELECT @Process, 'LogEvent' -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Start' -- INSERT INTO dbo.Parameters (Id, Char) SELECT @Id, '0.0' WHERE NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = @Id) -- SET @LastProcessed = (SELECT Char FROM dbo.Parameters WHERE Id = @Id) -- INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Insert',@Rows=@@rowcount -- SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 1) -- SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 2) -- DELETE FROM @Types WHERE ResourceTypeId < @ResourceTypeId -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Delete',@Rows=@@rowcount -- WHILE EXISTS (SELECT * FROM @Types) -- Processing in ASC order -- BEGIN -- SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types ORDER BY ResourceTypeId) -- SET @ProcessedResources = 0 -- SET @CurrentMaxSurrogateId = 0 -- WHILE @CurrentMaxSurrogateId IS NOT NULL -- BEGIN -- BEGIN TRANSACTION -- SET @CurrentMaxSurrogateId = NULL -- SELECT @CurrentMaxSurrogateId = max(ResourceSurrogateId), @RowsToProcess = count(*) -- FROM (SELECT TOP 5000 ResourceSurrogateId -- 5000 is max to avoid lock escalation -- FROM dbo.Resource (HOLDLOCK) -- Hold locks for the duration of 2 inserts, so other write transactions cannot change data -- WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @MaxSurrogateId -- ORDER BY ResourceSurrogateId -- ) A -- IF @CurrentMaxSurrogateId IS NOT NULL -- BEGIN -- SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@CurrentMaxSurrogateId) -- SET @st = getUTCdate() -- INSERT INTO dbo.ResourceCurrent -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM (SELECT * -- FROM dbo.Resource A WITH (INDEX = 1) -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId > @SurrogateId -- AND ResourceSurrogateId <= @CurrentMaxSurrogateId -- AND IsHistory = 0 -- ) A -- WHERE NOT EXISTS (SELECT * FROM dbo.ResourceCurrent B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- surr id from $import insert can point in the past -- OPTION (MAXDOP 1) -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceCurrent',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st -- SET @st = getUTCdate() -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM (SELECT TOP (@DummyTop) * -- FROM dbo.Resource A -- WHERE ResourceTypeId = @ResourceTypeId -- AND ResourceSurrogateId > @SurrogateId -- AND ResourceSurrogateId <= @CurrentMaxSurrogateId -- AND IsHistory = 1 -- ) A -- WHERE NOT EXISTS (SELECT * FROM dbo.ResourceHistory B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- history can be inserted by the new version insert in merge -- OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceHistory',@Action='Insert',@Rows=@@rowcount,@Text=@RowsToProcess,@Start=@st -- UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id -- COMMIT TRANSACTION -- SET @SurrogateId = @CurrentMaxSurrogateId -- SET @ProcessedResources += @RowsToProcess -- IF datediff(second, @ReportDate, getUTCdate()) > 60 -- BEGIN -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources -- SET @ReportDate = getUTCdate() -- SET @ProcessedResources = 0 -- END -- END -- ELSE -- BEGIN -- COMMIT TRANSACTION -- SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@MaxSurrogateId) -- UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id -- END -- END -- IF @ProcessedResources > 0 -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources -- DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId -- SET @SurrogateId = 0 -- END -- EXECUTE dbo.LogEvent @Process=@Process,@Status='End' -- END TRY -- BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. -- EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; -- THROW -- END CATCH -- -- Copy end ---------------------------------------------------------------------------------------------------------- -- DECLARE @OldRows bigint -- ,@CurrentRows bigint -- ,@HistoryRows bigint -- ,@msg varchar(1000) -- BEGIN TRY -- BEGIN TRANSACTION -- verification -- -- lock input -- SET @OldRows = (SELECT TOP 1 1 FROM dbo.Resource (TABLOCKX)) -- SET @OldRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('Resource') AND index_id IN (0,1)) -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='Resource',@Action='RowsCheck',@Text=@OldRows -- SET @CurrentRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceCurrent') AND index_id IN (0,1)) -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceCurrent',@Action='RowsCheck',@Text=@CurrentRows -- SET @HistoryRows = (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceHistory') AND index_id IN (0,1)) -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Target='ResourceHistory',@Action='RowsCheck',@Text=@HistoryRows -- IF @CurrentRows + @HistoryRows <> @OldRows -- BEGIN -- SET @msg = 'OldRows='+convert(varchar,@OldRows)+' <> NewRows='+convert(varchar,@CurrentRows + @HistoryRows) -- RAISERROR(@msg,18,127) -- END -- COMMIT TRANSACTION -- verification -- EXECUTE dbo.LogEvent @Process='HistorySeparation.Verification',@Status='Warn',@Text='Completed' -- EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Started' -- SET lock_timeout 180000 -- 3 minutes -- BEGIN TRANSACTION -- table - view switch -- IF EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'KeepResourceTable' AND Number = 1) -- EXECUTE sp_rename 'Resource', 'Resource_Table' -- ELSE -- DROP TABLE dbo.Resource -- --CREATE VIEW dbo.Resource -- EXECUTE(' --CREATE VIEW dbo.Resource --AS --SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsHistory -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM dbo.ResourceHistory --UNION ALL --SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsHistory -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,NULL -- FROM dbo.ResourceCurrent -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='Resource',@Action='Create' -- IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceIns' AND type = 'tr') -- DROP TRIGGER dbo.ResourceIns -- --CREATE TRIGGER dbo.ResourceIns -- EXECUTE(' --CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT --AS --BEGIN -- INSERT INTO dbo.ResourceCurrent -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- FROM Inserted -- WHERE IsHistory = 0 -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceIns',@Action='Create' -- IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceUpd' AND type = 'tr') -- DROP TRIGGER dbo.ResourceUpd -- --CREATE TRIGGER dbo.ResourceUpd -- EXECUTE(' --CREATE TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE --AS --BEGIN -- IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) -- BEGIN -- UPDATE B -- SET SearchParamHash = A.SearchParamHash -- this is the only update we support -- FROM Inserted A -- JOIN dbo.ResourceCurrent B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- WHERE A.IsHistory = 0 -- RETURN -- END -- IF NOT UPDATE(IsHistory) -- RAISERROR(''Generic updates are not supported via Resource view'',18,127) -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) -- INSERT INTO dbo.ResourceHistory -- ( -- ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- ) -- SELECT ResourceTypeId -- ,ResourceSurrogateId -- ,ResourceId -- ,Version -- ,IsDeleted -- ,RequestMethod -- ,RawResource -- ,IsRawResourceMetaSet -- ,SearchParamHash -- ,TransactionId -- ,HistoryTransactionId -- FROM Inserted -- WHERE IsHistory = 1 --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceUpd',@Action='Create' -- IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ResourceDel' AND type = 'tr') -- DROP TRIGGER dbo.ResourceDel -- --CREATE TRIGGER dbo.ResourceDel -- EXECUTE(' --CREATE TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE --AS --BEGIN -- DELETE FROM A -- FROM dbo.ResourceCurrent A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) -- DELETE FROM A -- FROM dbo.ResourceHistory A -- WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) --END -- ') -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Run',@Target='ResourceDel',@Action='Create' -- COMMIT TRANSACTION -- table - view switch -- EXECUTE dbo.LogEvent @Process='HistorySeparation.TableViewSwitch',@Status='Warn',@Text='Completed' -- END TRY -- BEGIN CATCH -- IF @@trancount > 0 ROLLBACK TRANSACTION -- EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='Error'; -- THROW -- END CATCH --END --GO --EXECUTE dbo.LogEvent @Process='HistorySeparation',@Status='End' --GO \ No newline at end of file +IF NOT EXISTS (SELECT * FROM sys.sequences WHERE name = 'ResourceIdIntMapSequence') +CREATE SEQUENCE dbo.ResourceIdIntMapSequence + AS int + START WITH 0 + INCREMENT BY 1 + MINVALUE 0 + MAXVALUE 79999 + CYCLE + CACHE 1000000 +GO +CREATE OR ALTER PROCEDURE dbo.AssignResourceIdInts @Count int, @FirstIdInt bigint OUT +AS +set nocount on +DECLARE @SP varchar(100) = 'AssignResourceIdInts' + ,@Mode varchar(200) = 'Cnt='+convert(varchar,@Count) + ,@st datetime = getUTCdate() + ,@FirstValueVar sql_variant + ,@LastValueVar sql_variant + ,@SequenceRangeFirstValue int + +BEGIN TRY + SET @FirstValueVar = NULL + WHILE @FirstValueVar IS NULL + BEGIN + EXECUTE sys.sp_sequence_get_range @sequence_name = 'dbo.ResourceIdIntMapSequence', @range_size = @Count, @range_first_value = @FirstValueVar OUT, @range_last_value = @LastValueVar OUT + SET @SequenceRangeFirstValue = convert(int,@FirstValueVar) + IF @SequenceRangeFirstValue > convert(int,@LastValueVar) + SET @FirstValueVar = NULL + END + + SET @FirstIdInt = datediff_big(millisecond,'0001-01-01',sysUTCdatetime()) * 80000 + @SequenceRangeFirstValue +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + THROW +END CATCH +GO +IF NOT EXISTS (SELECT * FROM sys.types WHERE name = 'ResourceListLake') +CREATE TYPE dbo.ResourceListLake AS TABLE +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,Version int NOT NULL + ,HasVersionToCompare bit NOT NULL -- in case of multiple versions per resource indicates that row contains (existing version + 1) value + ,IsDeleted bit NOT NULL + ,IsHistory bit NOT NULL + ,KeepHistory bit NOT NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,RequestMethod varchar(10) NULL + ,SearchParamHash varchar(64) NULL + ,OffsetInFile int NULL + + PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) + ,UNIQUE (ResourceTypeId, ResourceId, Version) +) +GO +IF EXISTS (SELECT * FROM sys.objects WHERE name = 'Resource' AND type = 'u') +BEGIN + BEGIN TRANSACTION + + EXECUTE sp_rename 'Resource', 'ResourceTbl' + + CREATE TABLE dbo.ResourceIdIntMap + ( + ResourceTypeId smallint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + + CONSTRAINT PKC_ResourceIdIntMap_ResourceIdInt_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_ResourceIdIntMap_ResourceId_ResourceTypeId UNIQUE (ResourceId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ) + + ALTER TABLE dbo.ResourceIdIntMap SET ( LOCK_ESCALATION = AUTO ) + + CREATE TABLE dbo.RawResources + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,RawResource varbinary(max) NULL + + CONSTRAINT PKC_RawResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ) + + ALTER TABLE dbo.RawResources SET ( LOCK_ESCALATION = AUTO ) + + CREATE TABLE dbo.CurrentResources + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,IsHistory bit NOT NULL CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL + ,FileId bigint NULL + ,OffsetInFile int NULL + + CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ) + + ALTER TABLE dbo.CurrentResources ADD CONSTRAINT FK_CurrentResources_ResourceIdInt_ResourceTypeId_ResourceIdIntMap FOREIGN KEY (ResourceIdInt, ResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + + ALTER TABLE dbo.CurrentResources SET ( LOCK_ESCALATION = AUTO ) + + CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.CurrentResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.CurrentResources (HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + CREATE TABLE dbo.HistoryResources + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,IsHistory bit NOT NULL CONSTRAINT DF_HistoryResources_IsHistory DEFAULT 1, CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1) + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_HistoryResources_IsRawResourceMetaSet DEFAULT 0 + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL + ,FileId bigint NULL + ,OffsetInFile int NULL + + CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ,CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + ) + + ALTER TABLE dbo.HistoryResources ADD CONSTRAINT FK_HistoryResources_ResourceIdInt_ResourceTypeId_ResourceIdIntMap FOREIGN KEY (ResourceIdInt, ResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + + ALTER TABLE dbo.HistoryResources SET ( LOCK_ESCALATION = AUTO ) + + CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.HistoryResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.HistoryResources (HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + EXECUTE(' +CREATE VIEW dbo.Resource +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,B.RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +UNION ALL +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,B.RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.HistoryResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,ResourceId + ,NULL + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,NULL + ,NULL + FROM dbo.ResourceTbl + ') + + COMMIT TRANSACTION +END +GO +CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT +AS +BEGIN + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + + INSERT INTO dbo.CurrentResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 0 + + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 1 +END +GO +CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE +AS +BEGIN + IF UPDATE(IsDeleted) AND UPDATE(RawResource) AND UPDATE(SearchParamHash) AND UPDATE(HistoryTransactionId) AND NOT UPDATE(IsHistory) -- hard delete resource + BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted A + JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + IF @@rowcount = 0 + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + + UPDATE B + SET IsDeleted = A.IsDeleted + ,SearchParamHash = A.SearchParamHash + ,HistoryTransactionId = A.HistoryTransactionId + FROM Inserted A + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + RETURN + END + + IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) -- reindex + BEGIN + UPDATE B + SET SearchParamHash = A.SearchParamHash + FROM Inserted A + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE A.IsHistory = 0 + + RETURN + END + + IF UPDATE(TransactionId) AND NOT UPDATE(IsHistory) -- cleanup trans + BEGIN + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted A + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0 + + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted A + JOIN dbo.HistoryResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1 + + RETURN + END + + IF UPDATE(RawResource) -- invisible records + BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted A + JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + IF @@rowcount = 0 + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + END + + IF NOT UPDATE(IsHistory) + RAISERROR('Generic updates are not supported via Resource view',18,127) + + DELETE FROM A + FROM dbo.CurrentResources A + WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) + + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 1 +END +GO +CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE +AS +BEGIN + DELETE FROM A + FROM dbo.CurrentResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) + + DELETE FROM A + FROM dbo.HistoryResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) + + DELETE FROM A + FROM dbo.RawResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END +GO +IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ReferenceSearchParam' AND type = 'u') +BEGIN + BEGIN TRANSACTION + + EXECUTE sp_rename 'ReferenceSearchParam', 'ReferenceSearchParamTbl' + + CREATE TABLE dbo.ResourceReferenceSearchParams + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,IsResourceRef bit NOT NULL CONSTRAINT DF_ResourceReferenceSearchParams_IsResourceRef DEFAULT 1, CONSTRAINT CH_ResourceReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 1) + ) + + ALTER TABLE dbo.ResourceReferenceSearchParams ADD CONSTRAINT FK_ResourceReferenceSearchParams_ReferenceResourceIdInt_ReferenceResourceTypeId_ResourceIdIntMap FOREIGN KEY (ReferenceResourceIdInt, ReferenceResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + + ALTER TABLE dbo.ResourceReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) + + CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.ResourceReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.ResourceReferenceSearchParams (ReferenceResourceIdInt, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + CREATE TABLE dbo.StringReferenceSearchParams + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL + ,IsResourceRef bit NOT NULL CONSTRAINT DF_StringReferenceSearchParams_IsResourceRef DEFAULT 0, CONSTRAINT CH_StringReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 0) + ) + + ALTER TABLE dbo.StringReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) + + CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.StringReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + CREATE UNIQUE INDEX IXU_ReferenceResourceId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.StringReferenceSearchParams (ReferenceResourceId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + EXECUTE(' +CREATE VIEW dbo.ReferenceSearchParam +AS +SELECT A.ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,ReferenceResourceTypeId + ,ReferenceResourceId = B.ResourceId + ,IsResourceRef + FROM dbo.ResourceReferenceSearchParams A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,NULL + ,ReferenceResourceId + ,IsResourceRef + FROM dbo.StringReferenceSearchParams +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,ReferenceResourceTypeId + ,ReferenceResourceId + ,NULL + FROM dbo.ReferenceSearchParamTbl + ') + + EXECUTE(' +CREATE TRIGGER dbo.ReferenceSearchParamDel ON dbo.ReferenceSearchParam INSTEAD OF DELETE +AS +BEGIN + DELETE FROM A + FROM dbo.ResourceReferenceSearchParams A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.IsResourceRef = 1 AND B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) + + DELETE FROM A + FROM dbo.StringReferenceSearchParams A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.IsResourceRef = 0 AND B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END + ') + + COMMIT TRANSACTION +END +GO +GO +BEGIN TRANSACTION +GO +DROP PROCEDURE MergeResources +DROP PROCEDURE UpdateResourceSearchParams +DROP TYPE ReferenceSearchParamList +GO +CREATE TYPE dbo.ReferenceSearchParamList AS TABLE +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NULL + ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ReferenceResourceVersion int NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId) +) +GO +CREATE PROCEDURE dbo.UpdateResourceSearchParams + @FailedResources int = 0 OUT + ,@Resources dbo.ResourceList READONLY + ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY + ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY + ,@TokenSearchParams dbo.TokenSearchParamList READONLY + ,@TokenTexts dbo.TokenTextList READONLY + ,@StringSearchParams dbo.StringSearchParamList READONLY + ,@UriSearchParams dbo.UriSearchParamList READONLY + ,@NumberSearchParams dbo.NumberSearchParamList READONLY + ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY + ,@DateTimeSearchParams dbo.DateTimeSearchParamList READONLY + ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY + ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY + ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY + ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY + ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY + ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = object_name(@@procid) + ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') + ,@Rows int + +BEGIN TRY + DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) + + BEGIN TRANSACTION + + -- Update the search parameter hash value in the main resource table + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 + SET @Rows = @@rowcount + + -- First, delete all the search params of the resources to reindex. + DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM dbo.ResourceReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + DELETE FROM B FROM dbo.StringReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + -- Next, insert all the new search params. + INSERT INTO dbo.ResourceWriteClaim + ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) + SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue + FROM @ResourceWriteClaims + + -- TODO: Add insert into ResourceIdIntMap + + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, B.ResourceIdInt + FROM @ReferenceSearchParams A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL + + INSERT INTO dbo.TokenSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow + FROM @TokenSearchParams + + INSERT INTO dbo.TokenText + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text + FROM @TokenTexts + + INSERT INTO dbo.StringSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax + FROM @StringSearchParams + + INSERT INTO dbo.UriSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri + FROM @UriSearchParams + + INSERT INTO dbo.NumberSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue + FROM @NumberSearchParams + + INSERT INTO dbo.QuantitySearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue + FROM @QuantitySearchParams + + INSERT INTO dbo.DateTimeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax + FROM @DateTimeSearchParams + + INSERT INTO dbo.ReferenceTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams + + INSERT INTO dbo.TokenTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 + FROM @TokenTokenCompositeSearchParams + + INSERT INTO dbo.TokenDateTimeCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams + + INSERT INTO dbo.TokenQuantityCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 + FROM @TokenQuantityCompositeSearchParams + + INSERT INTO dbo.TokenStringCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 + FROM @TokenStringCompositeSearchParams + + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange + FROM @TokenNumberNumberCompositeSearchParams + + COMMIT TRANSACTION + + SET @FailedResources = (SELECT count(*) FROM @Resources) - @Rows + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows +END TRY +BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + THROW +END CATCH +GO +CREATE PROCEDURE dbo.MergeResources +-- This stored procedure can be used for: +-- 1. Ordinary put with single version per resource in input +-- 2. Put with history preservation (multiple input versions per resource) +-- 3. Copy from one gen2 store to another with ResourceSurrogateId preserved. + @AffectedRows int = 0 OUT + ,@RaiseExceptionOnConflict bit = 1 + ,@IsResourceChangeCaptureEnabled bit = 0 + ,@TransactionId bigint = NULL + ,@SingleTransaction bit = 1 + ,@Resources dbo.ResourceList READONLY -- before lake code. TODO: Remove after deployment + ,@ResourcesLake dbo.ResourceListLake READONLY -- Lake code + ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY + ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY + ,@TokenSearchParams dbo.TokenSearchParamList READONLY + ,@TokenTexts dbo.TokenTextList READONLY + ,@StringSearchParams dbo.StringSearchParamList READONLY + ,@UriSearchParams dbo.UriSearchParamList READONLY + ,@NumberSearchParams dbo.NumberSearchParamList READONLY + ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY + ,@DateTimeSearchParms dbo.DateTimeSearchParamList READONLY + ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY + ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY + ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY + ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY + ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY + ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = object_name(@@procid) + ,@DummyTop bigint = 9223372036854775807 + ,@InitialTranCount int = @@trancount + ,@IsRetry bit = 0 + ,@RT smallint + ,@NewIdsCount int + ,@FirstIdInt bigint + +DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') +SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') + +SET @AffectedRows = 0 + +RetryResourceIdIntMapInsert: +BEGIN TRY + DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) + DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertIds AS TABLE (ResourceIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL) + DECLARE @InsertedIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ResourcesWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,HasVersionToCompare bit NOT NULL -- in case of multiple versions per resource indicates that row contains (existing version + 1) value + ,IsDeleted bit NOT NULL + ,IsHistory bit NOT NULL + ,KeepHistory bit NOT NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,RequestMethod varchar(10) NULL + ,SearchParamHash varchar(64) NULL + ,FileId bigint NULL + ,OffsetInFile int NULL + + PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) + ,UNIQUE (ResourceTypeId, ResourceIdInt, Version) + ) + DECLARE @ReferenceSearchParamsWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) + ) + + INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL + INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds + +-- Prepare id map for reference search params Start --------------------------------------------------------------------------- + WHILE EXISTS (SELECT * FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) + + INSERT INTO @ExistingIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT @RT, ResourceIdInt, A.ResourceId + FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId + + DELETE FROM @InsertIds + + INSERT INTO @InsertIds + ( ResourceIndex, ResourceId ) + SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId + FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A + WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + DELETE FROM @RTs WHERE ResourceTypeId = @RT + END + + INSERT INTO @ReferenceSearchParamsWithIds + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) + FROM (SELECT * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL) A + LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId +-- Prepare id map for reference search params End --------------------------------------------------------------------------- + + DELETE FROM @InputIds + DELETE FROM @RTs + DELETE FROM @InsertedIds + DELETE FROM @ExistingIds + +-- Prepare id map for resources Start --------------------------------------------------------------------------- + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId + FROM (SELECT ResourceTypeId, ResourceId FROM @ResourcesLake + UNION ALL + SELECT ResourceTypeId, ResourceId FROM @Resources -- TODO: Remove after deployment + ) A + GROUP BY ResourceTypeId, ResourceId + INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds + + WHILE EXISTS (SELECT * FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) + + INSERT INTO @ExistingIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT @RT, ResourceIdInt, A.ResourceId + FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId + + DELETE FROM @InsertIds + + INSERT INTO @InsertIds + ( ResourceIndex, ResourceId ) + SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId + FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A + WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + DELETE FROM @RTs WHERE ResourceTypeId = @RT + END + + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile + FROM (SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId = CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END, OffsetInFile FROM @ResourcesLake + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL FROM @Resources + ) A + LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Action='Insert',@Target='@ResourcesWithIds',@Rows=@@rowcount,@Start=@st + +-- Prepare id map for resources End --------------------------------------------------------------------------- +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' + BEGIN + DELETE FROM @ResourcesWithIds + DELETE FROM @ReferenceSearchParamsWithIds + DELETE FROM @InputIds + DELETE FROM @RTs + DELETE FROM @InsertedIds + DELETE FROM @ExistingIds + + GOTO RetryResourceIdIntMapInsert + END + ELSE + THROW +END CATCH + +--EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Text='ResourceIdIntMap populated' + +BEGIN TRY + DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) + + DECLARE @ResourceInfos AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,SurrogateId bigint NOT NULL + ,Version int NOT NULL + ,KeepHistory bit NOT NULL + ,PreviousVersion int NULL + ,PreviousSurrogateId bigint NULL + + PRIMARY KEY (ResourceTypeId, SurrogateId) + ) + + DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) + + IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 + SET @SingleTransaction = 1 + + SET @Mode += ' ST='+convert(varchar,@SingleTransaction) + + -- perform retry check in transaction to hold locks + IF @InitialTranCount = 0 + BEGIN + IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them + FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0 + ) + BEGIN + BEGIN TRANSACTION + + INSERT INTO @Existing + ( ResourceTypeId, SurrogateId ) + SELECT B.ResourceTypeId, B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * FROM @Resources) A + JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0 + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + IF @@rowcount = (SELECT count(*) FROM @Resources) SET @IsRetry = 1 + + IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction + END + END + + SET @Mode += ' R='+convert(varchar,@IsRetry) + + IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION + + IF @IsRetry = 0 + BEGIN + INSERT INTO @ResourceInfos + ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) + SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds WHERE HasVersionToCompare = 1) A + LEFT OUTER JOIN dbo.CurrentResources B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. + ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <= PreviousVersion) + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 + + INSERT INTO @PreviousSurrogateIds + SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory + FROM @ResourceInfos + WHERE PreviousSurrogateId IS NOT NULL + + IF @@rowcount > 0 + BEGIN + UPDATE dbo.Resource + SET IsHistory = 1 + WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) + SET @AffectedRows += @@rowcount + + IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) + UPDATE dbo.Resource + SET IsHistory = 1 + ,RawResource = 0xF -- "invisible" value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) + ELSE + DELETE FROM dbo.Resource WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) + SET @AffectedRows += @@rowcount + + DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenText WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.StringSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.UriSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.NumberSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.QuantitySearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.DateTimeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.ReferenceTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenDateTimeCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenQuantityCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenStringCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + + --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' + END + + INSERT INTO dbo.Resource + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, FileId, OffsetInFile + FROM @ResourcesWithIds + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ResourceWriteClaim + ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) + SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue + FROM @ResourceWriteClaims + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM @ReferenceSearchParamsWithIds + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow + FROM @TokenSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenText + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text + FROM @TokenTexts + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax + FROM @StringSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.UriSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri + FROM @UriSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.NumberSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue + FROM @NumberSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.QuantitySearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue + FROM @QuantitySearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.DateTimeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax + FROM @DateTimeSearchParms + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ReferenceTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 + FROM @TokenTokenCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenDateTimeCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenQuantityCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 + FROM @TokenQuantityCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenStringCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 + FROM @TokenStringCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange + FROM @TokenNumberNumberCompositeSearchParams + SET @AffectedRows += @@rowcount + END -- @IsRetry = 0 + ELSE + BEGIN -- @IsRetry = 1 + INSERT INTO dbo.ResourceWriteClaim + ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) + SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue + FROM (SELECT TOP (@DummyTop) * FROM @ResourceWriteClaims) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.ResourceWriteClaim C WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParamsWithIds) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NULL) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.StringReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow + FROM (SELECT TOP (@DummyTop) * FROM @TokenSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenText + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text + FROM (SELECT TOP (@DummyTop) * FROM @TokenTexts) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax + FROM (SELECT TOP (@DummyTop) * FROM @StringSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenText C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.UriSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri + FROM (SELECT TOP (@DummyTop) * FROM @UriSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.UriSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.NumberSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue + FROM (SELECT TOP (@DummyTop) * FROM @NumberSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.NumberSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.QuantitySearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue + FROM (SELECT TOP (@DummyTop) * FROM @QuantitySearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.QuantitySearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.DateTimeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax + FROM (SELECT TOP (@DummyTop) * FROM @DateTimeSearchParms) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ReferenceTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceTokenCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.DateTimeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenTokenCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenTokenCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenDateTimeCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenDateTimeCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenDateTimeCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenQuantityCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenQuantityCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenQuantityCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenStringCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenStringCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenStringCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange + FROM (SELECT TOP (@DummyTop) * FROM @TokenNumberNumberCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenNumberNumberCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + END + + IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. + EXECUTE dbo.CaptureResourceIdsForChanges @Resources + + IF @TransactionId IS NOT NULL + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + + IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') -- handles old and separated tables + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW +END CATCH +GO +COMMIT TRANSACTION +GO +ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = 'GetResources' + ,@InputRows int + ,@NotNullVersionExists bit + ,@NullVersionExists bit + ,@MinRT smallint + ,@MaxRT smallint + +SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys + +DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) + +BEGIN TRY + IF @NotNullVersionExists = 1 + IF @NullVersionExists = 0 + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + OPTION (MAXDOP 1) + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.IsHistory = 0 + ) A + OPTION (MAXDOP 1) + ELSE + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 + OPTION (MAXDOP 1) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + THROW +END CATCH +GO +ALTER PROCEDURE dbo.GetResourcesByTransactionId @TransactionId bigint, @IncludeHistory bit = 0, @ReturnResourceKeysOnly bit = 0 +AS +set nocount on +DECLARE @SP varchar(100) = object_name(@@procid) + ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId)+' H='+convert(varchar,@IncludeHistory) + ,@st datetime = getUTCdate() + +BEGIN TRY + IF @ReturnResourceKeysOnly = 0 + SELECT ResourceTypeId + ,ResourceId + ,ResourceSurrogateId + ,Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,RequestMethod + ,FileId + ,OffsetInFile + FROM dbo.Resource + WHERE TransactionId = @TransactionId AND (IsHistory = 0 OR @IncludeHistory = 1) + OPTION (MAXDOP 1) + ELSE + SELECT ResourceTypeId + ,ResourceId + ,ResourceSurrogateId + ,Version + ,IsDeleted + FROM dbo.Resource + WHERE TransactionId = @TransactionId AND (IsHistory = 0 OR @IncludeHistory = 1) + OPTION (MAXDOP 1) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + THROW +END CATCH +GO +ALTER PROCEDURE dbo.HardDeleteResource + @ResourceTypeId smallint + ,@ResourceId varchar(64) + ,@KeepCurrentVersion bit + ,@IsResourceChangeCaptureEnabled bit +AS +set nocount on +DECLARE @SP varchar(100) = object_name(@@procid) + ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled) + ,@st datetime = getUTCdate() + ,@TransactionId bigint + +BEGIN TRY + IF @IsResourceChangeCaptureEnabled = 1 EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT + + IF @KeepCurrentVersion = 0 + BEGIN TRANSACTION + + DECLARE @SurrogateIds TABLE (ResourceSurrogateId BIGINT NOT NULL) + + UPDATE dbo.Resource + SET IsDeleted = 1 + ,RawResource = 0xF -- invisible value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) + --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + + IF @KeepCurrentVersion = 0 + BEGIN + -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM dbo.ReferenceSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + END + + IF @@trancount > 0 COMMIT TRANSACTION + + IF @IsResourceChangeCaptureEnabled = 1 EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st +END TRY +BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + THROW +END CATCH +GO +-- Special version before data movement +ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY +AS +-- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = 'GetResourceVersions' + ,@Mode varchar(100) = 'Rows='+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) + ,@DummyTop bigint = 9223372036854775807 + +BEGIN TRY + SELECT A.ResourceTypeId + ,A.ResourceId + ,A.ResourceSurrogateId + -- set version to 0 if there is no gap available, or lastUpdated is already used. It would indicate potential conflict for the caller. + ,Version = CASE + -- ResourceSurrogateId is generated from lastUpdated only without extra bits at the end. Need to ckeck interval (0..79999) on resource id level. + WHEN D.Version IS NOT NULL THEN 0 -- input lastUpdated matches stored + WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex -- gap is available + ELSE isnull(M.Version, 0) - ResourceIndex -- late arrival + END + ,MatchedVersion = isnull(D.Version,0) + ,MatchedRawResource = D.RawResource + ,MatchedFileId = D.FileId + ,MatchedOffsetInFile = D.OffsetInFile + -- ResourceIndex allows to deal with more than one late arrival per resource + FROM (SELECT TOP (@DummyTop) A.*, ResourceIndex = convert(int,row_number() OVER (PARTITION BY A.ResourceTypeId, A.ResourceId ORDER BY ResourceSurrogateId DESC)) + FROM @ResourceDateKeys A + ) A + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version < 0 ORDER BY B.Version) M -- minus + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + THROW +END CATCH +GO +-- Move data +set nocount on +INSERT INTO dbo.Parameters (Id, Char) SELECT 'LakeSchemaUpgrade', 'LogEvent' + +DECLARE @Types TABLE (ResourceTypeId smallint PRIMARY KEY, Name varchar(100)) +DECLARE @MaxSurrogateId bigint = 0 + ,@ResourceTypeId smallint + +IF NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'LakeSchemaUpgrade.MaxSurrogateId') -- DELETE FROM dbo.Parameters WHERE Id = 'LakeSchemaUpgrade.MaxSurrogateId' +BEGIN + DECLARE @MaxSurrogateIdTmp bigint + + INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes + WHILE EXISTS (SELECT * FROM @Types) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types) + SET @MaxSurrogateIdTmp = (SELECT max(ResourceSurrogateId) FROM Resource WHERE ResourceTypeId = @ResourceTypeId) + IF @MaxSurrogateIdTmp > @MaxSurrogateId SET @MaxSurrogateId = @MaxSurrogateIdTmp + DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId + END + INSERT INTO dbo.Parameters (Id, Bigint) SELECT 'LakeSchemaUpgrade.MaxSurrogateId', @MaxSurrogateId +END + +SET @MaxSurrogateId = (SELECT Bigint FROM dbo.Parameters WHERE Id = 'LakeSchemaUpgrade.MaxSurrogateId') +EXECUTE dbo.LogEvent @Process='LakeSchemaUpgrade',@Status='Run',@Target='@MaxSurrogateId',@Action='Select',@Text=@MaxSurrogateId + +DECLARE @Process varchar(100) = 'LakeSchemaUpgrade.MoveResources' + ,@Id varchar(100) = 'LakeSchemaUpgrade.MoveResources.LastProcessed.TypeId.SurrogateId' -- SELECT * FROM Parameters + ,@SurrogateId bigint + ,@RowsToProcess int + ,@ProcessedResources int + ,@ReportDate datetime = getUTCdate() + ,@DummyTop bigint = 9223372036854775807 + ,@Rows int + ,@CurrentMaxSurrogateId bigint + ,@LastProcessed varchar(100) + ,@st datetime + ,@NewIdsCount int + ,@Count int + ,@FirstIdInt bigint + ,@RT smallint + +DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) +DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) +DECLARE @ExistingIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) +DECLARE @InsertIds AS TABLE (ResourceIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL) +DECLARE @InsertedIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + +BEGIN TRY + EXECUTE dbo.LogEvent @Process=@Process,@Status='Start' + + INSERT INTO dbo.Parameters (Id, Char) SELECT @Id, '0.0' + + SET @LastProcessed = (SELECT Char FROM dbo.Parameters WHERE Id = @Id) + + INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Insert',@Rows=@@rowcount + + SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 1) + SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 2) + + DELETE FROM @Types WHERE ResourceTypeId < @ResourceTypeId + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='@Types',@Action='Delete',@Rows=@@rowcount + + WHILE EXISTS (SELECT * FROM @Types) -- Processing in ASC order + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types ORDER BY ResourceTypeId) + + SET @ProcessedResources = 0 + SET @CurrentMaxSurrogateId = 0 + WHILE @CurrentMaxSurrogateId IS NOT NULL + BEGIN + BEGIN TRANSACTION + + SET @CurrentMaxSurrogateId = NULL + SELECT @CurrentMaxSurrogateId = max(ResourceSurrogateId), @RowsToProcess = count(*) + FROM (SELECT TOP 5000 ResourceSurrogateId + FROM dbo.ResourceTbl WITH (HOLDLOCK, ROWLOCK) + WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @MaxSurrogateId + ORDER BY ResourceSurrogateId + ) A + + IF @CurrentMaxSurrogateId IS NOT NULL + BEGIN + SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@CurrentMaxSurrogateId) + + DELETE FROM @InputIds + DELETE FROM @RTs + DELETE FROM @InsertedIds + DELETE FROM @ExistingIds + + RetryResourceIdIntMapInsert: + BEGIN TRY + SET @st = getUTCdate() + INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId + FROM dbo.ReferenceSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + AND ReferenceResourceTypeId IS NOT NULL + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParam.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + + INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds + + -- Prepare id map for reference search params Start --------------------------------------------------------------------------- + SET @st = getUTCdate() + SET @Count = 0 + WHILE EXISTS (SELECT * FROM @RTs) + BEGIN + SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) + + INSERT INTO @ExistingIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT @RT, ResourceIdInt, A.ResourceId + FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId + + DELETE FROM @InsertIds + + INSERT INTO @InsertIds + ( ResourceIndex, ResourceId ) + SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId + FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A + WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + SET @Count += @NewIdsCount + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + DELETE FROM @RTs WHERE ResourceTypeId = @RT + END + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParam.ResourceIdIntMap',@Action='Insert',@Rows=@Count,@Start=@st + + SET @st = getUTCdate() + SET @Count = 0 + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) + FROM (SELECT * + FROM dbo.ReferenceSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + AND ReferenceResourceTypeId IS NOT NULL + ) A + LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + SET @Count += @@rowcount + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM dbo.ReferenceSearchParamTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + AND ReferenceResourceTypeId IS NULL + SET @Count += @@rowcount + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParam',@Action='Insert',@Rows=@Count,@Start=@st + + SET @st = getUTCdate() + DELETE FROM dbo.ReferenceSearchParamTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + SET @Count += @@rowcount + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl',@Action='Delete',@Rows=@Count,@Start=@st + -- Prepare id map for reference search params End --------------------------------------------------------------------------- + + DELETE FROM @InputIds + DELETE FROM @RTs + DELETE FROM @InsertedIds + DELETE FROM @ExistingIds + + SET @st = getUTCdate() + INSERT INTO @InputIds SELECT @ResourceTypeId, ResourceId + FROM (SELECT ResourceId + FROM dbo.ResourceTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + ) A + GROUP BY ResourceId + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + SET @Count = 0 + INSERT INTO @ExistingIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT @ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceId = A.ResourceId + + DELETE FROM @InsertIds + + INSERT INTO @InsertIds + ( ResourceIndex, ResourceId ) + SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + OUTPUT @ResourceTypeId, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds + SELECT @ResourceTypeId, ResourceIndex + @FirstIdInt, ResourceId + FROM @InsertIds + SET @Count = @@rowcount + END + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource.ResourceIdIntMap',@Action='Insert',@Rows=@Count,@Start=@st + + SET @st = getUTCdate() + INSERT INTO dbo.Resource + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL + FROM dbo.ResourceTbl A + LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + WHERE A.ResourceTypeId = @ResourceTypeId + AND A.ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + DELETE FROM dbo.ResourceTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st + END TRY + BEGIN CATCH + EXECUTE dbo.LogEvent @Process=@Process,@Mode=@LastProcessed,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' + BEGIN + GOTO RetryResourceIdIntMapInsert + END + ELSE + THROW + END CATCH + + UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id + + COMMIT TRANSACTION + + SET @SurrogateId = @CurrentMaxSurrogateId + + SET @ProcessedResources += @RowsToProcess + + IF datediff(second, @ReportDate, getUTCdate()) > 60 + BEGIN + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources + SET @ReportDate = getUTCdate() + SET @ProcessedResources = 0 + END + END + ELSE + BEGIN + COMMIT TRANSACTION + SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@MaxSurrogateId) + UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id + END + END + + IF @ProcessedResources > 0 + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Select',@Rows=@ProcessedResources + + DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId + + SET @SurrogateId = 0 + END + + EXECUTE dbo.LogEvent @Process=@Process,@Status='End' +END TRY +BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; + THROW +END CATCH +GO +ALTER VIEW dbo.ReferenceSearchParam +AS +SELECT A.ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,ReferenceResourceTypeId + ,ReferenceResourceId = B.ResourceId + ,IsResourceRef + FROM dbo.ResourceReferenceSearchParams A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,SearchParamId + ,BaseUri + ,NULL + ,ReferenceResourceId + ,IsResourceRef + FROM dbo.StringReferenceSearchParams +GO +ALTER VIEW dbo.Resource +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,B.RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +UNION ALL +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,B.RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.HistoryResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +GO +ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY +AS +-- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = 'GetResourceVersions' + ,@Mode varchar(100) = 'Rows='+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) + ,@DummyTop bigint = 9223372036854775807 + +BEGIN TRY + SELECT A.ResourceTypeId + ,A.ResourceId + ,A.ResourceSurrogateId + -- set version to 0 if there is no gap available, or lastUpdated is already used. It would indicate potential conflict for the caller. + ,Version = CASE + -- ResourceSurrogateId is generated from lastUpdated only without extra bits at the end. Need to ckeck interval (0..79999) on resource id level. + WHEN D.Version IS NOT NULL THEN 0 -- input lastUpdated matches stored + WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex -- gap is available + ELSE isnull(M.Version, 0) - ResourceIndex -- late arrival + END + ,MatchedVersion = isnull(D.Version,0) + ,MatchedRawResource = D.RawResource + ,MatchedFileId = D.FileId + ,MatchedOffsetInFile = D.OffsetInFile + -- ResourceIndex allows to deal with more than one late arrival per resource + FROM (SELECT TOP (@DummyTop) A.*, M.ResourceIdInt, ResourceIndex = convert(int,row_number() OVER (PARTITION BY A.ResourceTypeId, A.ResourceId ORDER BY ResourceSurrogateId DESC)) + FROM @ResourceDateKeys A + LEFT OUTER JOIN dbo.ResourceIdIntMap M WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON M.ResourceTypeId = A.ResourceTypeId AND M.ResourceId = A.ResourceId + ) A + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.Version < 0 ORDER BY B.Version) M -- minus + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + THROW +END CATCH +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 333c0f60f6..ebeadc2796 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -2995,7 +2995,7 @@ BEGIN TRY SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - C.Version, + B.Version, IsDeleted, IsHistory, RawResource, @@ -3006,21 +3006,17 @@ BEGIN TRY FROM (SELECT * FROM @ResourceKeys) AS A INNER LOOP JOIN - dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + dbo.Resource AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN - dbo.Resource AS C - ON C.ResourceTypeId = A.ResourceTypeId - AND C.ResourceIdInt = B.ResourceIdInt - AND C.Version = A.Version + AND B.Version = A.Version OPTION (MAXDOP 1); ELSE SELECT * FROM (SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - C.Version, + B.Version, IsDeleted, IsHistory, RawResource, @@ -3032,19 +3028,15 @@ BEGIN TRY FROM @ResourceKeys WHERE Version IS NOT NULL) AS A INNER LOOP JOIN - dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + dbo.Resource AS B ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = A.ResourceId - INNER LOOP JOIN - dbo.Resource AS C - ON C.ResourceTypeId = A.ResourceTypeId - AND C.ResourceIdInt = B.ResourceIdInt - AND C.Version = A.Version + AND B.ResourceId = B.ResourceId + AND B.Version = A.Version UNION ALL SELECT B.ResourceTypeId, B.ResourceId, - C.ResourceSurrogateId, - C.Version, + ResourceSurrogateId, + B.Version, IsDeleted, IsHistory, RawResource, @@ -3056,24 +3048,16 @@ BEGIN TRY FROM @ResourceKeys WHERE Version IS NULL) AS A INNER LOOP JOIN - dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + dbo.Resource AS B ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = A.ResourceId - INNER LOOP JOIN - dbo.CurrentResources AS C - ON C.ResourceTypeId = A.ResourceTypeId - AND C.ResourceIdInt = B.ResourceIdInt - AND C.IsHistory = 0 - LEFT OUTER JOIN - dbo.RawResources AS D - ON D.ResourceTypeId = A.ResourceTypeId - AND D.ResourceSurrogateId = C.ResourceSurrogateId) AS A + AND B.ResourceId = B.ResourceId + AND B.IsHistory = 0) AS A OPTION (MAXDOP 1); ELSE SELECT B.ResourceTypeId, B.ResourceId, - C.ResourceSurrogateId, - C.Version, + ResourceSurrogateId, + B.Version, IsDeleted, IsHistory, RawResource, @@ -3084,17 +3068,10 @@ BEGIN TRY FROM (SELECT * FROM @ResourceKeys) AS A INNER LOOP JOIN - dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) + dbo.Resource AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN - dbo.CurrentResources AS C - ON C.ResourceTypeId = A.ResourceTypeId - AND C.ResourceIdInt = B.ResourceIdInt - LEFT OUTER JOIN - dbo.RawResources AS D - ON D.ResourceTypeId = A.ResourceTypeId - AND D.ResourceSurrogateId = C.ResourceSurrogateId + AND B.IsHistory = 0 OPTION (MAXDOP 1); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; END TRY @@ -3333,7 +3310,7 @@ BEGIN TRY CASE WHEN D.Version IS NOT NULL THEN 0 WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex ELSE isnull(M.Version, 0) - ResourceIndex END AS Version, isnull(D.Version, 0) AS MatchedVersion, D.RawResource AS MatchedRawResource, - D.TransactionId AS MatchedTransactionId, + D.FileId AS MatchedFileId, D.OffsetInFile AS MatchedOffsetInFile FROM (SELECT TOP (@DummyTop) A.*, M.ResourceIdInt, diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs index 38762c29be..d552c5fc1b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs @@ -7,7 +7,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema { public static class SchemaVersionConstants { - public const int Min = (int)SchemaVersion.V80; + public const int Min = (int)SchemaVersion.V83; public const int Max = (int)SchemaVersion.V84; public const int MinForUpgrade = (int)SchemaVersion.V80; // this is used for upgrade tests only public const int SearchParameterStatusSchemaVersion = (int)SchemaVersion.V6; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql index 6e3219ad68..3b13cbd923 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourceVersions.sql @@ -22,7 +22,7 @@ BEGIN TRY END ,MatchedVersion = isnull(D.Version,0) ,MatchedRawResource = D.RawResource - ,MatchedTransactionId = D.TransactionId + ,MatchedFileId = D.FileId ,MatchedOffsetInFile = D.OffsetInFile -- ResourceIndex allows to deal with more than one late arrival per resource FROM (SELECT TOP (@DummyTop) A.*, M.ResourceIdInt, ResourceIndex = convert(int,row_number() OVER (PARTITION BY A.ResourceTypeId, A.ResourceId ORDER BY ResourceSurrogateId DESC)) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index 5e3ab4aa0f..6626d68249 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -21,7 +21,7 @@ BEGIN TRY SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,C.Version + ,B.Version ,IsDeleted ,IsHistory ,RawResource @@ -30,15 +30,14 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version OPTION (MAXDOP 1) ELSE SELECT * FROM (SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,C.Version + ,B.Version ,IsDeleted ,IsHistory ,RawResource @@ -47,13 +46,12 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId - ,C.ResourceSurrogateId - ,C.Version + ,ResourceSurrogateId + ,B.Version ,IsDeleted ,IsHistory ,RawResource @@ -62,16 +60,14 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 - LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.IsHistory = 0 ) A OPTION (MAXDOP 1) ELSE SELECT B.ResourceTypeId ,B.ResourceId - ,C.ResourceSurrogateId - ,C.Version + ,ResourceSurrogateId + ,B.Version ,IsDeleted ,IsHistory ,RawResource @@ -80,9 +76,7 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt - LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 9c81358844..189b5796d1 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -14,6 +14,7 @@ using Microsoft.Health.Fhir.Core.Features.Search; using Microsoft.Health.Fhir.Core.Features.Search.Expressions; using Microsoft.Health.Fhir.Core.Models; +using Microsoft.Health.Fhir.SqlServer.Features.Schema; using Microsoft.Health.Fhir.SqlServer.Features.Schema.Model; using Microsoft.Health.Fhir.SqlServer.Features.Storage; using Microsoft.Health.SqlServer; @@ -204,8 +205,11 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions StringBuilder.Append(VLatest.Resource.RawResource, resourceTableAlias); - StringBuilder.Append(", ").Append(VLatest.Resource.TransactionId, resourceTableAlias); - StringBuilder.Append(", ").Append(VLatest.Resource.OffsetInFile, resourceTableAlias); + if (_schemaInfo.Current >= SchemaVersionConstants.Lake) + { + StringBuilder.Append(", ").Append(VLatest.Resource.FileId, resourceTableAlias); + StringBuilder.Append(", ").Append(VLatest.Resource.OffsetInFile, resourceTableAlias); + } if (IsSortValueNeeded(context)) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 6120eb9fa1..946de9b7db 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -852,8 +852,8 @@ private void ReadWrapper( isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 8); searchParameterHash = reader.Read(VLatest.Resource.SearchParamHash, 9); rawResourceSqlBytes = reader.GetSqlBytes(10); - fileId = reader.Read(VLatest.Resource.FileId, 11); - offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, 12); + fileId = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.FileId, 11) : null; + offsetInFile = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.OffsetInFile, 12) : null; isInvisible = false; if (!rawResourceSqlBytes.IsNull) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index 4d330b250c..73dd960b51 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -762,7 +762,7 @@ internal async Task MergeResourcesWrapperAsync(long transactionId, bool singleTr cmd.Parameters.AddWithValue("@IsResourceChangeCaptureEnabled", _coreFeatures.SupportsResourceChangeCapture); cmd.Parameters.AddWithValue("@TransactionId", transactionId); cmd.Parameters.AddWithValue("@SingleTransaction", singleTransaction); - if (SqlAdlsStore.AdlsClient != null) + if (_schemaInformation.Current >= SchemaVersionConstants.Lake && SqlAdlsStore.AdlsClient != null) { await PutRawResourcesIntoAdls(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource } @@ -849,7 +849,15 @@ public async Task BulkUpdateSearchParameterIndicesAsync(IReadOnlyCollection new MergeResourceWrapper(_, false, false)).ToList(); using var cmd = new SqlCommand("dbo.UpdateResourceSearchParams") { CommandType = CommandType.StoredProcedure, CommandTimeout = 300 + (int)(3600.0 / 10000 * mergeWrappers.Count) }; - new ResourceListTableValuedParameterDefinition("@Resources").AddParameter(cmd.Parameters, new ResourceListRowGenerator(_model, _compressedRawResourceConverter).GenerateRows(mergeWrappers)); + if (_schemaInformation.Current >= SchemaVersionConstants.Lake) + { + new ResourceListLakeTableValuedParameterDefinition("@ResourcesLake").AddParameter(cmd.Parameters, new ResourceListLakeRowGenerator(_model, _compressedRawResourceConverter).GenerateRows(mergeWrappers)); + } + else + { + new ResourceListTableValuedParameterDefinition("@Resources").AddParameter(cmd.Parameters, new ResourceListRowGenerator(_model, _compressedRawResourceConverter).GenerateRows(mergeWrappers)); + } + new ResourceWriteClaimListTableValuedParameterDefinition("@ResourceWriteClaims").AddParameter(cmd.Parameters, new ResourceWriteClaimListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); new ReferenceSearchParamListTableValuedParameterDefinition("@ReferenceSearchParams").AddParameter(cmd.Parameters, new ReferenceSearchParamListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); new TokenSearchParamListTableValuedParameterDefinition("@TokenSearchParams").AddParameter(cmd.Parameters, new TokenSearchParamListRowGenerator(_model, _searchParameterTypeMap).GenerateRows(mergeWrappers)); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 0372c51313..a51065b88c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -130,8 +130,8 @@ public static Lazy GetRawResourceFromAdls(long fileId, int offsetInFile) { matchedVersion = reader.Read(table.Version, 4).ToString(); var bytes = reader.GetSqlBytes(5); - var matchedFileId = reader.Read(table.FileId, 6); - var matchedOffsetInFile = reader.Read(table.OffsetInFile, 7); + var matchedFileId = reader.FieldCount > 6 ? reader.Read(table.FileId, 6) : null; // TODO: Remove field count check after deployment + var matchedOffsetInFile = reader.FieldCount > 6 ? reader.Read(table.OffsetInFile, 7) : null; matchedRawResource = new RawResource(ReadRawResource(bytes, decompress, matchedFileId, matchedOffsetInFile), FhirResourceFormat.Json, true); } @@ -180,8 +180,8 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re var isDeleted = reader.Read(VLatest.Resource.IsDeleted, 4); var isHistory = reader.Read(VLatest.Resource.IsHistory, 5); var bytes = reader.GetSqlBytes(6); - var fileId = reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9); - var offsetInFile = reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10); + var fileId = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9) : null; // TODO: Remove field count check after deployment + var offsetInFile = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10) : null; var rawResource = ReadRawResource(bytes, decompress, fileId, offsetInFile); var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); var searchParamHash = reader.Read(VLatest.Resource.SearchParamHash, 8); From 7f17c96f4dfa8d3217468399fd3eb64e18a15cd5 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 25 Nov 2024 14:09:22 -0800 Subject: [PATCH 034/111] GetResources back --- .../Features/Schema/Migrations/84.diff.sql | 182 +++++++++++++++++- .../Features/Schema/Migrations/84.sql | 55 ++++-- .../Schema/Sql/Sprocs/GetResources.sql | 26 ++- 3 files changed, 227 insertions(+), 36 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 1386c1f511..e6cc2f25c3 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -200,6 +200,162 @@ SELECT ResourceTypeId FROM dbo.ResourceTbl ') +EXECUTE(' +ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = ''GetResources'' + ,@InputRows int + ,@DummyTop bigint = 9223372036854775807 + ,@NotNullVersionExists bit + ,@NullVersionExists bit + ,@MinRT smallint + ,@MaxRT smallint + +SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys + +DECLARE @Mode varchar(100) = ''RT=[''+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+''] Cnt=''+convert(varchar,@InputRows)+'' NNVE=''+convert(varchar,@NotNullVersionExists)+'' NVE=''+convert(varchar,@NullVersionExists) + +BEGIN TRY + IF @NotNullVersionExists = 1 + IF @NullVersionExists = 0 + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,NULL + ,NULL + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + ) A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,C.ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,NULL + ,NULL + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,NULL + ,NULL + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0 + ) A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,C.ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A + JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0 + ) A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st; + THROW +END CATCH + ') + COMMIT TRANSACTION END GO @@ -1222,7 +1378,7 @@ BEGIN TRY SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -1231,14 +1387,15 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version OPTION (MAXDOP 1) ELSE SELECT * FROM (SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -1247,12 +1404,13 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.Version = A.Version + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId - ,ResourceSurrogateId - ,B.Version + ,C.ResourceSurrogateId + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -1261,14 +1419,16 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.IsHistory = 0 + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId ) A OPTION (MAXDOP 1) ELSE SELECT B.ResourceTypeId ,B.ResourceId - ,ResourceSurrogateId - ,B.Version + ,C.ResourceSurrogateId + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -1277,7 +1437,9 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index ebeadc2796..dcdb1ce289 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -2995,7 +2995,7 @@ BEGIN TRY SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - B.Version, + C.Version, IsDeleted, IsHistory, RawResource, @@ -3006,17 +3006,21 @@ BEGIN TRY FROM (SELECT * FROM @ResourceKeys) AS A INNER LOOP JOIN - dbo.Resource AS B + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - AND B.Version = A.Version + INNER LOOP JOIN + dbo.Resource AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.Version = A.Version OPTION (MAXDOP 1); ELSE SELECT * FROM (SELECT B.ResourceTypeId, B.ResourceId, ResourceSurrogateId, - B.Version, + C.Version, IsDeleted, IsHistory, RawResource, @@ -3028,15 +3032,19 @@ BEGIN TRY FROM @ResourceKeys WHERE Version IS NOT NULL) AS A INNER LOOP JOIN - dbo.Resource AS B + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = B.ResourceId - AND B.Version = A.Version + AND B.ResourceId = A.ResourceId + INNER LOOP JOIN + dbo.Resource AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.Version = A.Version UNION ALL SELECT B.ResourceTypeId, B.ResourceId, - ResourceSurrogateId, - B.Version, + C.ResourceSurrogateId, + C.Version, IsDeleted, IsHistory, RawResource, @@ -3048,16 +3056,24 @@ BEGIN TRY FROM @ResourceKeys WHERE Version IS NULL) AS A INNER LOOP JOIN - dbo.Resource AS B + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceId = B.ResourceId - AND B.IsHistory = 0) AS A + AND B.ResourceId = A.ResourceId + INNER LOOP JOIN + dbo.CurrentResources AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + AND C.IsHistory = 0 + LEFT OUTER JOIN + dbo.RawResources AS D + ON D.ResourceTypeId = A.ResourceTypeId + AND D.ResourceSurrogateId = C.ResourceSurrogateId) AS A OPTION (MAXDOP 1); ELSE SELECT B.ResourceTypeId, B.ResourceId, - ResourceSurrogateId, - B.Version, + C.ResourceSurrogateId, + C.Version, IsDeleted, IsHistory, RawResource, @@ -3068,10 +3084,17 @@ BEGIN TRY FROM (SELECT * FROM @ResourceKeys) AS A INNER LOOP JOIN - dbo.Resource AS B + dbo.ResourceIdIntMap AS B WITH (INDEX (U_ResourceIdIntMap_ResourceId_ResourceTypeId)) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - AND B.IsHistory = 0 + INNER LOOP JOIN + dbo.CurrentResources AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN + dbo.RawResources AS D + ON D.ResourceTypeId = A.ResourceTypeId + AND D.ResourceSurrogateId = C.ResourceSurrogateId OPTION (MAXDOP 1); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; END TRY diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql index 6626d68249..5e3ab4aa0f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResources.sql @@ -21,7 +21,7 @@ BEGIN TRY SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -30,14 +30,15 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version OPTION (MAXDOP 1) ELSE SELECT * FROM (SELECT B.ResourceTypeId ,B.ResourceId ,ResourceSurrogateId - ,B.Version + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -46,12 +47,13 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.Version = A.Version + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version UNION ALL SELECT B.ResourceTypeId ,B.ResourceId - ,ResourceSurrogateId - ,B.Version + ,C.ResourceSurrogateId + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -60,14 +62,16 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = B.ResourceId AND B.IsHistory = 0 + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId ) A OPTION (MAXDOP 1) ELSE SELECT B.ResourceTypeId ,B.ResourceId - ,ResourceSurrogateId - ,B.Version + ,C.ResourceSurrogateId + ,C.Version ,IsDeleted ,IsHistory ,RawResource @@ -76,7 +80,9 @@ BEGIN TRY ,FileId ,OffsetInFile FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.IsHistory = 0 + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId OPTION (MAXDOP 1) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount From 8b660a023b075b247e25562cd1214f3112010f5c Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 3 Dec 2024 18:19:50 -0800 Subject: [PATCH 035/111] Fix diff --- .../Features/Schema/Migrations/84.diff.sql | 227 ++++++++++-------- 1 file changed, 127 insertions(+), 100 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index e6cc2f25c3..ef4ee09c7f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -200,7 +200,7 @@ SELECT ResourceTypeId FROM dbo.ResourceTbl ') -EXECUTE(' + EXECUTE(' ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY AS set nocount on @@ -215,7 +215,7 @@ DECLARE @st datetime = getUTCdate() SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys -DECLARE @Mode varchar(100) = ''RT=[''+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+''] Cnt=''+convert(varchar,@InputRows)+'' NNVE=''+convert(varchar,@NotNullVersionExists)+'' NVE=''+convert(varchar,@NullVersionExists) +DECLARE @Mode varchar(100) = ''RT=[''+convert(varchar,@MinRT)+'',''+convert(varchar,@MaxRT)+''] Cnt=''+convert(varchar,@InputRows)+'' NNVE=''+convert(varchar,@NotNullVersionExists)+'' NVE=''+convert(varchar,@NullVersionExists) BEGIN TRY IF @NotNullVersionExists = 1 @@ -312,7 +312,7 @@ BEGIN TRY FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 - ) A + ) A OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) ELSE SELECT * @@ -341,8 +341,10 @@ BEGIN TRY ,RawResource ,IsRawResourceMetaSet ,SearchParamHash + ,NULL + ,NULL FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.Resource B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId WHERE IsHistory = 0 ) A OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) @@ -365,20 +367,23 @@ BEGIN INSERT INTO dbo.RawResources ( ResourceTypeId, ResourceSurrogateId, RawResource ) SELECT ResourceTypeId, ResourceSurrogateId, RawResource - FROM Inserted + FROM Inserted A WHERE RawResource IS NOT NULL + AND NOT EXISTS (SELECT * FROM dbo.RawResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) INSERT INTO dbo.CurrentResources ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile - FROM Inserted + FROM Inserted A WHERE IsHistory = 0 + AND NOT EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) INSERT INTO dbo.HistoryResources ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile - FROM Inserted + FROM Inserted A WHERE IsHistory = 1 + AND NOT EXISTS (SELECT * FROM dbo.HistoryResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) END GO CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE @@ -1355,100 +1360,29 @@ BEGIN CATCH THROW END CATCH GO -COMMIT TRANSACTION -GO -ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY +CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT AS -set nocount on -DECLARE @st datetime = getUTCdate() - ,@SP varchar(100) = 'GetResources' - ,@InputRows int - ,@NotNullVersionExists bit - ,@NullVersionExists bit - ,@MinRT smallint - ,@MaxRT smallint - -SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys - -DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) +BEGIN + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL -BEGIN TRY - IF @NotNullVersionExists = 1 - IF @NullVersionExists = 0 - SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version - OPTION (MAXDOP 1) - ELSE - SELECT * - FROM (SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version - UNION ALL - SELECT B.ResourceTypeId - ,B.ResourceId - ,C.ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 - LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId - ) A - OPTION (MAXDOP 1) - ELSE - SELECT B.ResourceTypeId - ,B.ResourceId - ,C.ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt - LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId - OPTION (MAXDOP 1) + INSERT INTO dbo.CurrentResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 0 - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount -END TRY -BEGIN CATCH - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - THROW -END CATCH + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 1 +END +GO +COMMIT TRANSACTION GO ALTER PROCEDURE dbo.GetResourcesByTransactionId @TransactionId bigint, @IncludeHistory bit = 0, @ReturnResourceKeysOnly bit = 0 AS @@ -1693,7 +1627,7 @@ BEGIN TRY BEGIN TRY SET @st = getUTCdate() INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId - FROM dbo.ReferenceSearchParam + FROM dbo.ReferenceSearchParamTbl WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND ReferenceResourceTypeId IS NOT NULL @@ -1745,7 +1679,7 @@ BEGIN TRY ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) FROM (SELECT * - FROM dbo.ReferenceSearchParam + FROM dbo.ReferenceSearchParamTbl WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND ReferenceResourceTypeId IS NOT NULL @@ -1989,3 +1923,96 @@ BEGIN CATCH THROW END CATCH GO +ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = 'GetResources' + ,@InputRows int + ,@NotNullVersionExists bit + ,@NullVersionExists bit + ,@MinRT smallint + ,@MaxRT smallint + +SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys + +DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) + +BEGIN TRY + IF @NotNullVersionExists = 1 + IF @NullVersionExists = 0 + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + OPTION (MAXDOP 1) + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,C.ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + ) A + OPTION (MAXDOP 1) + ELSE + SELECT B.ResourceTypeId + ,B.ResourceId + ,C.ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + OPTION (MAXDOP 1) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + THROW +END CATCH +GO From 9992090b416a75bb01ff7760a260d95b263426cb Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 4 Dec 2024 13:11:27 -0800 Subject: [PATCH 036/111] Use ResourceListLake correctly --- .../Features/Schema/Migrations/84.diff.sql | 27 +++++++++---- .../Features/Schema/Migrations/84.sql | 38 +++++++++++++++---- .../Sprocs/CaptureResourceIdsForChanges.sql | 4 +- .../Schema/Sql/Sprocs/MergeResources.sql | 15 ++++---- 4 files changed, 59 insertions(+), 25 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index ef4ee09c7f..99ff002ad0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -582,9 +582,9 @@ END COMMIT TRANSACTION END GO -GO BEGIN TRANSACTION GO +DROP PROCEDURE CaptureResourceIdsForChanges DROP PROCEDURE MergeResources DROP PROCEDURE UpdateResourceSearchParams DROP TYPE ReferenceSearchParamList @@ -602,6 +602,16 @@ CREATE TYPE dbo.ReferenceSearchParamList AS TABLE UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId) ) GO +CREATE PROCEDURE dbo.CaptureResourceIdsForChanges @Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY +AS +set nocount on +-- This procedure is intended to be called from the MergeResources procedure and relies on its transaction logic +INSERT INTO dbo.ResourceChangeData + ( ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId ) + SELECT ResourceId, ResourceTypeId, Version, CASE WHEN IsDeleted = 1 THEN 2 WHEN Version > 1 THEN 1 ELSE 0 END + FROM (SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @Resources UNION ALL SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @ResourcesLake) A + WHERE IsHistory = 0 +GO CREATE PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT ,@Resources dbo.ResourceList READONLY @@ -794,7 +804,7 @@ DECLARE @st datetime = getUTCdate() ,@NewIdsCount int ,@FirstIdInt bigint -DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') +DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),'Input=Empty') SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') SET @AffectedRows = 0 @@ -810,6 +820,7 @@ BEGIN TRY ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ,ResourceIdInt bigint NOT NULL ,Version int NOT NULL ,HasVersionToCompare bit NOT NULL -- in case of multiple versions per resource indicates that row contains (existing version + 1) value @@ -931,8 +942,8 @@ BEGIN TRY END INSERT INTO @ResourcesWithIds - ( ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) - SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile FROM (SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId = CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END, OffsetInFile FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL FROM @Resources @@ -992,7 +1003,7 @@ BEGIN TRY IF @InitialTranCount = 0 BEGIN IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them - FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + FROM @ResourcesWithIds A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 ) BEGIN @@ -1001,14 +1012,14 @@ BEGIN TRY INSERT INTO @Existing ( ResourceTypeId, SurrogateId ) SELECT B.ResourceTypeId, B.ResourceSurrogateId - FROM (SELECT TOP (@DummyTop) * FROM @Resources) A + FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds) A JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 AND B.ResourceId = A.ResourceId AND B.Version = A.Version OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - IF @@rowcount = (SELECT count(*) FROM @Resources) SET @IsRetry = 1 + IF @@rowcount = (SELECT count(*) FROM @ResourcesWithIds) SET @IsRetry = 1 IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction END @@ -1339,7 +1350,7 @@ BEGIN TRY END IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. - EXECUTE dbo.CaptureResourceIdsForChanges @Resources + EXECUTE dbo.CaptureResourceIdsForChanges @Resources, @ResourcesLake IF @TransactionId IS NOT NULL EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index dcdb1ce289..0d733dfd7d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -1536,7 +1536,7 @@ END GO CREATE PROCEDURE dbo.CaptureResourceIdsForChanges -@Resources dbo.ResourceList READONLY +@Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY AS SET NOCOUNT ON; INSERT INTO dbo.ResourceChangeData (ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId) @@ -1544,7 +1544,19 @@ SELECT ResourceId, ResourceTypeId, Version, CASE WHEN IsDeleted = 1 THEN 2 WHEN Version > 1 THEN 1 ELSE 0 END -FROM @Resources +FROM (SELECT ResourceId, + ResourceTypeId, + Version, + IsHistory, + IsDeleted + FROM @Resources + UNION ALL + SELECT ResourceId, + ResourceTypeId, + Version, + IsHistory, + IsDeleted + FROM @ResourcesLake) AS A WHERE IsHistory = 0; GO @@ -3648,7 +3660,15 @@ AS SET NOCOUNT ON; DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0, @RT AS SMALLINT, @NewIdsCount AS INT, @FirstIdInt AS BIGINT; DECLARE @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) - FROM @Resources), 'Input=Empty'); + FROM (SELECT ResourceTypeId, + ResourceSurrogateId, + Version + FROM @Resources + UNION ALL + SELECT ResourceTypeId, + ResourceSurrogateId, + Version + FROM @ResourcesLake) AS A), 'Input=Empty'); SET @Mode += ' E=' + CONVERT (VARCHAR, @RaiseExceptionOnConflict) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled) + ' IT=' + CONVERT (VARCHAR, @InitialTranCount) + ' T=' + isnull(CONVERT (VARCHAR, @TransactionId), 'NULL'); SET @AffectedRows = 0; RetryResourceIdIntMapInsert: @@ -3672,6 +3692,7 @@ BEGIN TRY DECLARE @ResourcesWithIds AS TABLE ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, ResourceIdInt BIGINT NOT NULL, Version INT NOT NULL, HasVersionToCompare BIT NOT NULL, @@ -3820,8 +3841,9 @@ BEGIN TRY DELETE @RTs WHERE ResourceTypeId = @RT; END - INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile) + INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile) SELECT A.ResourceTypeId, + A.ResourceId, isnull(C.ResourceIdInt, B.ResourceIdInt), Version, HasVersionToCompare, @@ -3920,7 +3942,7 @@ BEGIN TRY IF @InitialTranCount = 0 BEGIN IF EXISTS (SELECT * - FROM @Resources AS A + FROM @ResourcesWithIds AS A INNER JOIN dbo.Resource AS B ON B.ResourceTypeId = A.ResourceTypeId @@ -3932,7 +3954,7 @@ BEGIN TRY SELECT B.ResourceTypeId, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * - FROM @Resources) AS A + FROM @ResourcesWithIds) AS A INNER JOIN dbo.Resource AS B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId @@ -3942,7 +3964,7 @@ BEGIN TRY AND B.Version = A.Version OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); IF @@rowcount = (SELECT count(*) - FROM @Resources) + FROM @ResourcesWithIds) SET @IsRetry = 1; IF @IsRetry = 0 COMMIT TRANSACTION; @@ -4615,7 +4637,7 @@ BEGIN TRY SET @AffectedRows += @@rowcount; END IF @IsResourceChangeCaptureEnabled = 1 - EXECUTE dbo.CaptureResourceIdsForChanges @Resources; + EXECUTE dbo.CaptureResourceIdsForChanges @Resources, @ResourcesLake; IF @TransactionId IS NOT NULL EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; IF @InitialTranCount = 0 diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CaptureResourceIdsForChanges.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CaptureResourceIdsForChanges.sql index 9afaf3007c..85322776a8 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CaptureResourceIdsForChanges.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CaptureResourceIdsForChanges.sql @@ -1,10 +1,10 @@ -CREATE PROCEDURE dbo.CaptureResourceIdsForChanges @Resources dbo.ResourceList READONLY +CREATE PROCEDURE dbo.CaptureResourceIdsForChanges @Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY AS set nocount on -- This procedure is intended to be called from the MergeResources procedure and relies on its transaction logic INSERT INTO dbo.ResourceChangeData ( ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId ) SELECT ResourceId, ResourceTypeId, Version, CASE WHEN IsDeleted = 1 THEN 2 WHEN Version > 1 THEN 1 ELSE 0 END - FROM @Resources + FROM (SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @Resources UNION ALL SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @ResourcesLake) A WHERE IsHistory = 0 GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 5681678ab0..8066e28317 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -38,7 +38,7 @@ DECLARE @st datetime = getUTCdate() ,@NewIdsCount int ,@FirstIdInt bigint -DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') +DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),'Input=Empty') SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') SET @AffectedRows = 0 @@ -54,6 +54,7 @@ BEGIN TRY ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL ,ResourceIdInt bigint NOT NULL ,Version int NOT NULL ,HasVersionToCompare bit NOT NULL -- in case of multiple versions per resource indicates that row contains (existing version + 1) value @@ -175,8 +176,8 @@ BEGIN TRY END INSERT INTO @ResourcesWithIds - ( ResourceTypeId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) - SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile FROM (SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId = CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END, OffsetInFile FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL FROM @Resources @@ -236,7 +237,7 @@ BEGIN TRY IF @InitialTranCount = 0 BEGIN IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them - FROM @Resources A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + FROM @ResourcesWithIds A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 ) BEGIN @@ -245,14 +246,14 @@ BEGIN TRY INSERT INTO @Existing ( ResourceTypeId, SurrogateId ) SELECT B.ResourceTypeId, B.ResourceSurrogateId - FROM (SELECT TOP (@DummyTop) * FROM @Resources) A + FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds) A JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 AND B.ResourceId = A.ResourceId AND B.Version = A.Version OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - IF @@rowcount = (SELECT count(*) FROM @Resources) SET @IsRetry = 1 + IF @@rowcount = (SELECT count(*) FROM @ResourcesWithIds) SET @IsRetry = 1 IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction END @@ -583,7 +584,7 @@ BEGIN TRY END IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. - EXECUTE dbo.CaptureResourceIdsForChanges @Resources + EXECUTE dbo.CaptureResourceIdsForChanges @Resources, @ResourcesLake IF @TransactionId IS NOT NULL EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId From daa5c53b81c41e5af45b834f23c90e8945de075b Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 4 Dec 2024 17:00:12 -0800 Subject: [PATCH 037/111] Added @ResourceListLake to update resource search params --- .../Features/Schema/Migrations/84.diff.sql | 27 ++++++---- .../Features/Schema/Migrations/84.sql | 54 +++++++++++++------ .../Sql/Sprocs/UpdateResourceSearchParams.sql | 27 ++++++---- .../Features/Storage/SqlStoreClient.cs | 4 +- 4 files changed, 77 insertions(+), 35 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 99ff002ad0..77fc994439 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -614,7 +614,8 @@ INSERT INTO dbo.ResourceChangeData GO CREATE PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT - ,@Resources dbo.ResourceList READONLY + ,@Resources dbo.ResourceList READONLY -- TODO: Remove after deployment + ,@ResourcesLake dbo.ResourceListLake READONLY ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY ,@TokenSearchParams dbo.TokenSearchParamList READONLY @@ -634,7 +635,7 @@ AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') + ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),'Input=Empty') ,@Rows int BEGIN TRY @@ -643,12 +644,20 @@ BEGIN TRY BEGIN TRANSACTION -- Update the search parameter hash value in the main resource table - UPDATE B - SET SearchParamHash = (SELECT SearchParamHash FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids - FROM dbo.Resource B - WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - AND B.IsHistory = 0 + IF EXISTS (SELECT * FROM @ResourcesLake) + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash FROM @ResourcesLake A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @ResourcesLake A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 + ELSE + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 SET @Rows = @@rowcount -- First, delete all the search params of the resources to reindex. @@ -756,7 +765,7 @@ BEGIN TRY COMMIT TRANSACTION - SET @FailedResources = (SELECT count(*) FROM @Resources) - @Rows + SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @Rows EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows END TRY diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 0d733dfd7d..52da069943 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -5410,28 +5410,51 @@ COMMIT TRANSACTION; GO CREATE PROCEDURE dbo.UpdateResourceSearchParams -@FailedResources INT=0 OUTPUT, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParams dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +@FailedResources INT=0 OUTPUT, @Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParams dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS SET NOCOUNT ON; DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) - FROM @Resources), 'Input=Empty'), @Rows AS INT; + FROM (SELECT ResourceTypeId, + ResourceSurrogateId, + Version + FROM @ResourcesLake + UNION ALL + SELECT ResourceTypeId, + ResourceSurrogateId, + Version + FROM @Resources) AS A), 'Input=Empty'), @Rows AS INT; BEGIN TRY DECLARE @Ids TABLE ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL); BEGIN TRANSACTION; - UPDATE B - SET SearchParamHash = (SELECT SearchParamHash - FROM @Resources AS A - WHERE A.ResourceTypeId = B.ResourceTypeId - AND A.ResourceSurrogateId = B.ResourceSurrogateId) - OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids - FROM dbo.Resource AS B - WHERE EXISTS (SELECT * - FROM @Resources AS A - WHERE A.ResourceTypeId = B.ResourceTypeId - AND A.ResourceSurrogateId = B.ResourceSurrogateId) - AND B.IsHistory = 0; + IF EXISTS (SELECT * + FROM @ResourcesLake) + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash + FROM @ResourcesLake AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource AS B + WHERE EXISTS (SELECT * + FROM @ResourcesLake AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0; + ELSE + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash + FROM @Resources AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource AS B + WHERE EXISTS (SELECT * + FROM @Resources AS A + WHERE A.ResourceTypeId = B.ResourceTypeId + AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0; SET @Rows = @@rowcount; DELETE B FROM @Ids AS A @@ -5684,7 +5707,8 @@ BEGIN TRY FROM @TokenNumberNumberCompositeSearchParams; COMMIT TRANSACTION; SET @FailedResources = (SELECT count(*) - FROM @Resources) - @Rows; + FROM @Resources) + (SELECT count(*) + FROM @ResourcesLake) - @Rows; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; END TRY BEGIN CATCH diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql index ba423b78e6..5e43010cf4 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql @@ -1,6 +1,7 @@ CREATE PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT - ,@Resources dbo.ResourceList READONLY + ,@Resources dbo.ResourceList READONLY -- TODO: Remove after deployment + ,@ResourcesLake dbo.ResourceListLake READONLY ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY ,@TokenSearchParams dbo.TokenSearchParamList READONLY @@ -20,7 +21,7 @@ AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM @Resources),'Input=Empty') + ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),'Input=Empty') ,@Rows int BEGIN TRY @@ -29,12 +30,20 @@ BEGIN TRY BEGIN TRANSACTION -- Update the search parameter hash value in the main resource table - UPDATE B - SET SearchParamHash = (SELECT SearchParamHash FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids - FROM dbo.Resource B - WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - AND B.IsHistory = 0 + IF EXISTS (SELECT * FROM @ResourcesLake) + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash FROM @ResourcesLake A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @ResourcesLake A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 + ELSE + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 SET @Rows = @@rowcount -- First, delete all the search params of the resources to reindex. @@ -142,7 +151,7 @@ BEGIN TRY COMMIT TRANSACTION - SET @FailedResources = (SELECT count(*) FROM @Resources) - @Rows + SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @Rows EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows END TRY diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index a51065b88c..e29449624b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -180,8 +180,8 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re var isDeleted = reader.Read(VLatest.Resource.IsDeleted, 4); var isHistory = reader.Read(VLatest.Resource.IsHistory, 5); var bytes = reader.GetSqlBytes(6); - var fileId = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9) : null; // TODO: Remove field count check after deployment - var offsetInFile = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10) : null; + var fileId = reader.FieldCount > 10 ? reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9) : null; // TODO: Remove field count check after deployment + var offsetInFile = reader.FieldCount > 10 ? reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10) : null; var rawResource = ReadRawResource(bytes, decompress, fileId, offsetInFile); var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); var searchParamHash = reader.Read(VLatest.Resource.SearchParamHash, 8); From cfa461ca8996f0d315e9bd6168d2eb0698b25c23 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 11 Dec 2024 15:05:24 -0800 Subject: [PATCH 038/111] tweeking --- .../Features/Schema/Migrations/84.diff.sql | 1681 ++++++++++++++--- .../Features/Schema/Migrations/84.sql | 816 +++++--- .../Schema/Sql/Sprocs/HardDeleteResource.sql | 57 +- .../Schema/Sql/Sprocs/MergeResources.sql | 269 +-- .../MergeResourcesDeleteInvisibleHistory.sql | 59 +- .../Sql/Sprocs/UpdateResourceSearchParams.sql | 159 +- .../Schema/Sql/Types/ResourceListLake.sql | 1 + .../Schema/Sql/Views/ReferenceSearchParam.sql | 12 - .../Storage/SqlServerFhirDataStore.cs | 3 +- .../Features/Storage/SqlStoreClient.cs | 3 +- .../Merge/MergeResourceWrapper.cs | 5 + .../Merge/ResourceListLakeRowGenerator.cs | 2 +- tools/PerfTester/Program.cs | 10 +- 13 files changed, 2396 insertions(+), 681 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 77fc994439..d9fd87e69a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -52,6 +52,7 @@ CREATE TYPE dbo.ResourceListLake AS TABLE ,IsRawResourceMetaSet bit NOT NULL ,RequestMethod varchar(10) NULL ,SearchParamHash varchar(64) NULL + ,FileId bigint NULL ,OffsetInFile int NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) @@ -612,6 +613,8 @@ INSERT INTO dbo.ResourceChangeData FROM (SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @Resources UNION ALL SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @ResourcesLake) A WHERE IsHistory = 0 GO +-- The following 2 procs are special for data movement +GO CREATE PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT ,@Resources dbo.ResourceList READONLY -- TODO: Remove after deployment @@ -636,10 +639,66 @@ set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),'Input=Empty') - ,@Rows int + ,@ResourceRows int + ,@InsertRows int + ,@DeletedIdMap int + ,@FirstIdInt bigint + ,@CurrentRows int +RetryResourceIdIntMapLogic: BEGIN TRY DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) + DECLARE @CurrentRefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @CurrentRefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + DECLARE @InputRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertRefIds AS TABLE (ResourceTypeId smallint NOT NULL, IdIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ReferenceSearchParamsWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,ReferenceResourceVersion int NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) + ) + + -- Prepare insert into ResourceIdIntMap outside of transaction to minimize blocking + INSERT INTO @InputRefIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL + + INSERT INTO @ExistingRefIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputRefIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + + INSERT INTO @InsertRefIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputRefIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingRefIds B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @InsertRows = (SELECT count(*) FROM @InsertRefIds) + IF @InsertRows > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @InsertRows, @FirstIdInt OUT + + INSERT INTO @InsertedRefIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertRefIds + END + + INSERT INTO @ReferenceSearchParamsWithIds + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), ReferenceResourceVersion + FROM @ReferenceSearchParams A + LEFT OUTER JOIN @InsertedRefIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingRefIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId BEGIN TRANSACTION @@ -658,39 +717,72 @@ BEGIN TRY FROM dbo.Resource B WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) AND B.IsHistory = 0 - SET @Rows = @@rowcount + SET @ResourceRows = @@rowcount -- First, delete all the search params of the resources to reindex. - DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM dbo.ResourceReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - DELETE FROM B FROM dbo.StringReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceSearchParamTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + FROM @Ids A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- Next, insert all the new search params. INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims + + -- start delete logic from ResourceIdIntMap + INSERT INTO @CurrentRefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @CurrentRefIdsRaw + SET @CurrentRows = @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove not reused + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM @ReferenceSearchParamsWithIds B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced by resources + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced by reference search params + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- finally delete from id map + DELETE FROM B FROM @CurrentRefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END - -- TODO: Add insert into ResourceIdIntMap + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedRefIds INSERT INTO dbo.ResourceReferenceSearchParams - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) - SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, B.ResourceIdInt - FROM @ReferenceSearchParams A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM @ReferenceSearchParamsWithIds INSERT INTO dbo.StringReferenceSearchParams ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) @@ -765,14 +857,31 @@ BEGIN TRY COMMIT TRANSACTION - SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @Rows + SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @ResourceRows - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@ResourceRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - THROW + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation + OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @Ids + DELETE FROM @InputRefIds + DELETE FROM @CurrentRefIdsRaw + DELETE FROM @CurrentRefIds + DELETE FROM @ExistingRefIds + DELETE FROM @InsertRefIds + DELETE FROM @InsertedRefIds + DELETE FROM @ReferenceSearchParamsWithIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + THROW END CATCH GO CREATE PROCEDURE dbo.MergeResources @@ -812,19 +921,24 @@ DECLARE @st datetime = getUTCdate() ,@RT smallint ,@NewIdsCount int ,@FirstIdInt bigint + ,@CurrentRows int + ,@DeletedIdMap int DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),'Input=Empty') SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') SET @AffectedRows = 0 -RetryResourceIdIntMapInsert: +RetryResourceIdIntMapLogic: BEGIN TRY - DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) - DECLARE @ExistingIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) - DECLARE @InsertIds AS TABLE (ResourceIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL) - DECLARE @InsertedIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @CurrentRefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @CurrentRefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + DECLARE @ExistingIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertIds AS TABLE (ResourceTypeId smallint NOT NULL, IdIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) DECLARE @ResourcesWithIds AS TABLE ( ResourceTypeId smallint NOT NULL @@ -858,135 +972,89 @@ BEGIN TRY UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) ) + -- Prepare id map for reference search params Start --------------------------------------------------------------------------- INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL - INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds - --- Prepare id map for reference search params Start --------------------------------------------------------------------------- - WHILE EXISTS (SELECT * FROM @RTs) - BEGIN - SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) - INSERT INTO @ExistingIds - ( ResourceTypeId, ResourceIdInt, ResourceId ) - SELECT @RT, ResourceIdInt, A.ResourceId - FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId + INSERT INTO @ExistingIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - DELETE FROM @InsertIds - - INSERT INTO @InsertIds - ( ResourceIndex, ResourceId ) - SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId - FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A - WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) - - SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - - INSERT INTO dbo.ResourceIdIntMap - ( ResourceTypeId, ResourceIdInt, ResourceId ) - OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId - FROM @InsertIds - END + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsReference B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - DELETE FROM @RTs WHERE ResourceTypeId = @RT + INSERT INTO @InsertedIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds END INSERT INTO @ReferenceSearchParamsWithIds ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) - FROM (SELECT * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL) A - LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId - LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId --- Prepare id map for reference search params End --------------------------------------------------------------------------- + FROM @ReferenceSearchParams A + LEFT OUTER JOIN @InsertedIdsReference B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingIdsReference C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + -- Prepare id map for reference search params End --------------------------------------------------------------------------- + -- Prepare id map for resources Start --------------------------------------------------------------------------- DELETE FROM @InputIds - DELETE FROM @RTs - DELETE FROM @InsertedIds - DELETE FROM @ExistingIds - --- Prepare id map for resources Start --------------------------------------------------------------------------- - INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId - FROM (SELECT ResourceTypeId, ResourceId FROM @ResourcesLake - UNION ALL - SELECT ResourceTypeId, ResourceId FROM @Resources -- TODO: Remove after deployment - ) A - GROUP BY ResourceTypeId, ResourceId - INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds - - WHILE EXISTS (SELECT * FROM @RTs) + IF EXISTS (SELECT * FROM @ResourcesLake) + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @ResourcesLake GROUP BY ResourceTypeId, ResourceId + ELSE + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @Resources GROUP BY ResourceTypeId, ResourceId + + INSERT INTO @ExistingIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), A.ResourceId + FROM @InputIds A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @InsertedIdsReference C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + WHERE C.ResourceIdInt IS NOT NULL OR B.ResourceIdInt IS NOT NULL + + DELETE FROM @InsertIds + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsResource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 BEGIN - SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) - - INSERT INTO @ExistingIds - ( ResourceTypeId, ResourceIdInt, ResourceId ) - SELECT @RT, ResourceIdInt, A.ResourceId - FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId - - DELETE FROM @InsertIds - - INSERT INTO @InsertIds - ( ResourceIndex, ResourceId ) - SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId - FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A - WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) - - SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - INSERT INTO dbo.ResourceIdIntMap - ( ResourceTypeId, ResourceIdInt, ResourceId ) - OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId - FROM @InsertIds - END - - DELETE FROM @RTs WHERE ResourceTypeId = @RT + INSERT INTO @InsertedIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds END - INSERT INTO @ResourcesWithIds - ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) - SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile - FROM (SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId = CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END, OffsetInFile FROM @ResourcesLake - UNION ALL - SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL FROM @Resources - ) A - LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId - --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Action='Insert',@Target='@ResourcesWithIds',@Rows=@@rowcount,@Start=@st - --- Prepare id map for resources End --------------------------------------------------------------------------- -END TRY -BEGIN CATCH - IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st - - IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' - BEGIN - DELETE FROM @ResourcesWithIds - DELETE FROM @ReferenceSearchParamsWithIds - DELETE FROM @InputIds - DELETE FROM @RTs - DELETE FROM @InsertedIds - DELETE FROM @ExistingIds - - GOTO RetryResourceIdIntMapInsert - END + IF EXISTS (SELECT * FROM @ResourcesLake) + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile + FROM @ResourcesLake A + LEFT OUTER JOIN @InsertedIdsResource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIdsResource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId ELSE - THROW -END CATCH - ---EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Text='ResourceIdIntMap populated' + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL + FROM @Resources A + LEFT OUTER JOIN @InsertedIdsResource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIdsResource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + -- Prepare id map for resources End --------------------------------------------------------------------------- -BEGIN TRY DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) DECLARE @ResourceInfos AS TABLE @@ -1076,7 +1144,41 @@ BEGIN TRY DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount - DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + DELETE FROM dbo.ReferenceSearchParamTbl WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.ResourceReferenceSearchParams + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @CurrentRows = @@rowcount + SET @AffectedRows += @CurrentRows + -- start deleting from ResourceIdIntMap + INSERT INTO @CurrentRefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @CurrentRefIdsRaw + SET @CurrentRows = @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove not reused + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM @ReferenceSearchParamsWithIds B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced in Resources + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove still referenced in ResourceReferenceSearchParams + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- delete from id map + DELETE FROM B FROM @CurrentRefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END + DELETE FROM dbo.StringReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount @@ -1108,6 +1210,16 @@ BEGIN TRY --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' END + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsResource + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsReference + INSERT INTO dbo.Resource ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile ) SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, FileId, OffsetInFile @@ -1366,18 +1478,38 @@ BEGIN TRY IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st - IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') -- handles old and separated tables - THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; - ELSE - THROW + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation + OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @ResourcesWithIds + DELETE FROM @ReferenceSearchParamsWithIds + DELETE FROM @CurrentRefIdsRaw + DELETE FROM @CurrentRefIds + DELETE FROM @InputIds + DELETE FROM @InsertIds + DELETE FROM @InsertedIdsReference + DELETE FROM @ExistingIdsReference + DELETE FROM @InsertedIdsResource + DELETE FROM @ExistingIdsResource + DELETE FROM @Existing + DELETE FROM @ResourceInfos + DELETE FROM @PreviousSurrogateIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW END CATCH GO CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT @@ -1386,8 +1518,9 @@ BEGIN INSERT INTO dbo.RawResources ( ResourceTypeId, ResourceSurrogateId, RawResource ) SELECT ResourceTypeId, ResourceSurrogateId, RawResource - FROM Inserted + FROM Inserted A WHERE RawResource IS NOT NULL + AND NOT EXISTS (SELECT * FROM dbo.RawResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- Avoid dups caused by hard deletes INSERT INTO dbo.CurrentResources ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) @@ -1404,6 +1537,74 @@ END GO COMMIT TRANSACTION GO +ALTER PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId bigint, @AffectedRows int = NULL OUT +AS +set nocount on +DECLARE @SP varchar(100) = object_name(@@procid) + ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId) + ,@st datetime + ,@Rows int + ,@DeletedIdMap int + +SET @AffectedRows = 0 + +Retry: +BEGIN TRY + DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + + BEGIN TRANSACTION + + SET @st = getUTCdate() + DELETE FROM A + OUTPUT deleted.ResourceTypeId, deleted.ResourceIdInt INTO @Ids + FROM dbo.Resource A + WHERE HistoryTransactionId = @TransactionId + SET @Rows = @@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@Rows + SET @AffectedRows += @Rows + + SET @st = getUTCdate() + IF @Rows > 0 + BEGIN + -- remove referenced in resources + DELETE FROM A FROM @Ids A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + -- remove referenced in reference search params + DELETE FROM A FROM @Ids A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + -- delete from id map + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap + + COMMIT TRANSACTION + + SET @st = getUTCdate() + UPDATE dbo.Resource SET TransactionId = NULL WHERE TransactionId = @TransactionId + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Target='Resource',@Action='Update',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error' + IF error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @Ids + GOTO Retry + END + ELSE + THROW +END CATCH +GO +-- Special versions of procedures for data movement +GO ALTER PROCEDURE dbo.GetResourcesByTransactionId @TransactionId bigint, @IncludeHistory bit = 0, @ReturnResourceKeysOnly bit = 0 AS set nocount on @@ -1446,25 +1647,72 @@ BEGIN CATCH THROW END CATCH GO +ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY +AS +-- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = 'GetResourceVersions' + ,@Mode varchar(100) = 'Rows='+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) + ,@DummyTop bigint = 9223372036854775807 + +BEGIN TRY + SELECT A.ResourceTypeId + ,A.ResourceId + ,A.ResourceSurrogateId + -- set version to 0 if there is no gap available, or lastUpdated is already used. It would indicate potential conflict for the caller. + ,Version = CASE + -- ResourceSurrogateId is generated from lastUpdated only without extra bits at the end. Need to ckeck interval (0..79999) on resource id level. + WHEN D.Version IS NOT NULL THEN 0 -- input lastUpdated matches stored + WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex -- gap is available + ELSE isnull(M.Version, 0) - ResourceIndex -- late arrival + END + ,MatchedVersion = isnull(D.Version,0) + ,MatchedRawResource = D.RawResource + ,MatchedFileId = D.FileId + ,MatchedOffsetInFile = D.OffsetInFile + -- ResourceIndex allows to deal with more than one late arrival per resource + FROM (SELECT TOP (@DummyTop) A.*, ResourceIndex = convert(int,row_number() OVER (PARTITION BY A.ResourceTypeId, A.ResourceId ORDER BY ResourceSurrogateId DESC)) + FROM @ResourceDateKeys A + ) A + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version < 0 ORDER BY B.Version) M -- minus + OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + THROW +END CATCH +GO ALTER PROCEDURE dbo.HardDeleteResource @ResourceTypeId smallint ,@ResourceId varchar(64) ,@KeepCurrentVersion bit - ,@IsResourceChangeCaptureEnabled bit + ,@IsResourceChangeCaptureEnabled bit = 1 -- TODO: Remove input parameter after deployment AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled) + ,@Mode varchar(200) = ' RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) ,@st datetime = getUTCdate() ,@TransactionId bigint + ,@DeletedIdMap int + ,@Rows int BEGIN TRY - IF @IsResourceChangeCaptureEnabled = 1 EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT + EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT + SET @Mode = 'T='+convert(varchar,@TransactionId) + @Mode + + RetryResourceIdIntMapLogic: IF @KeepCurrentVersion = 0 BEGIN TRANSACTION - DECLARE @SurrogateIds TABLE (ResourceSurrogateId BIGINT NOT NULL) + DECLARE @SurrogateIds TABLE (ResourceSurrogateId bigint NOT NULL) UPDATE dbo.Resource SET IsDeleted = 1 @@ -1479,9 +1727,33 @@ BEGIN TRY IF @KeepCurrentVersion = 0 BEGIN + DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @RefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM dbo.ReferenceSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceSearchParamTbl B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw + FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + INSERT INTO @RefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw + SET @Rows = @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM B FROM @RefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) @@ -1499,60 +1771,28 @@ BEGIN TRY IF @@trancount > 0 COMMIT TRANSACTION - IF @IsResourceChangeCaptureEnabled = 1 EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - THROW -END CATCH -GO --- Special version before data movement -ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY -AS --- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated -set nocount on -DECLARE @st datetime = getUTCdate() - ,@SP varchar(100) = 'GetResourceVersions' - ,@Mode varchar(100) = 'Rows='+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) - ,@DummyTop bigint = 9223372036854775807 - -BEGIN TRY - SELECT A.ResourceTypeId - ,A.ResourceId - ,A.ResourceSurrogateId - -- set version to 0 if there is no gap available, or lastUpdated is already used. It would indicate potential conflict for the caller. - ,Version = CASE - -- ResourceSurrogateId is generated from lastUpdated only without extra bits at the end. Need to ckeck interval (0..79999) on resource id level. - WHEN D.Version IS NOT NULL THEN 0 -- input lastUpdated matches stored - WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex -- gap is available - ELSE isnull(M.Version, 0) - ResourceIndex -- late arrival - END - ,MatchedVersion = isnull(D.Version,0) - ,MatchedRawResource = D.RawResource - ,MatchedFileId = D.FileId - ,MatchedOffsetInFile = D.OffsetInFile - -- ResourceIndex allows to deal with more than one late arrival per resource - FROM (SELECT TOP (@DummyTop) A.*, ResourceIndex = convert(int,row_number() OVER (PARTITION BY A.ResourceTypeId, A.ResourceId ORDER BY ResourceSurrogateId DESC)) - FROM @ResourceDateKeys A - ) A - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId < A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId DESC) L -- lower - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version > 0 AND B.ResourceSurrogateId > A.ResourceSurrogateId ORDER BY B.ResourceSurrogateId) U -- upper - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version < 0 ORDER BY B.Version) M -- minus - OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() = 547 -- reference violation + BEGIN + DELETE FROM @SurrogateIds + DELETE FROM @RefIdsRaw + DELETE FROM @RefIds - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount -END TRY -BEGIN CATCH - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + GOTO RetryResourceIdIntMapLogic + END + ; THROW END CATCH GO -- Move data +-- ROLLBACK TRANSACTION set nocount on INSERT INTO dbo.Parameters (Id, Char) SELECT 'LakeSchemaUpgrade', 'LogEvent' @@ -1594,6 +1834,8 @@ DECLARE @Process varchar(100) = 'LakeSchemaUpgrade.MoveResources' ,@FirstIdInt bigint ,@RT smallint +INSERT INTO dbo.Parameters (Id, Char) SELECT @Process, 'LogEvent' + DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) DECLARE @ExistingIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) @@ -1651,7 +1893,7 @@ BEGIN TRY WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND ReferenceResourceTypeId IS NOT NULL - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParam.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds @@ -1694,11 +1936,10 @@ BEGIN TRY EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParam.ResourceIdIntMap',@Action='Insert',@Rows=@Count,@Start=@st SET @st = getUTCdate() - SET @Count = 0 INSERT INTO dbo.ResourceReferenceSearchParams ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) - FROM (SELECT * + FROM (SELECT TOP (@DummyTop) * FROM dbo.ReferenceSearchParamTbl WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId @@ -1706,8 +1947,10 @@ BEGIN TRY ) A LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId - SET @Count += @@rowcount + OPTION (OPTIMIZE FOR (@DummyTop = 1)) + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceReferenceSearchParams',@Action='Insert',@Rows=@@rowcount,@Start=@st + SET @st = getUTCdate() INSERT INTO dbo.StringReferenceSearchParams ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId @@ -1715,15 +1958,13 @@ BEGIN TRY WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId AND ReferenceResourceTypeId IS NULL - SET @Count += @@rowcount - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParam',@Action='Insert',@Rows=@Count,@Start=@st + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='StringReferenceSearchParams',@Action='Insert',@Rows=@@rowcount,@Start=@st SET @st = getUTCdate() DELETE FROM dbo.ReferenceSearchParamTbl WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - SET @Count += @@rowcount - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl',@Action='Delete',@Rows=@Count,@Start=@st + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st -- Prepare id map for reference search params End --------------------------------------------------------------------------- DELETE FROM @InputIds @@ -1732,14 +1973,16 @@ BEGIN TRY DELETE FROM @ExistingIds SET @st = getUTCdate() - INSERT INTO @InputIds SELECT @ResourceTypeId, ResourceId - FROM (SELECT ResourceId - FROM dbo.ResourceTbl - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - ) A - GROUP BY ResourceId - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + INSERT INTO @InputIds + SELECT @ResourceTypeId, ResourceId + FROM (SELECT ResourceId + FROM dbo.ResourceTbl WITH (INDEX = 1) + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + ) A + GROUP BY ResourceId + OPTION (MAXDOP 1) + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceTbl.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st SET @st = getUTCdate() SET @Count = 0 @@ -1850,6 +2093,7 @@ SELECT A.ResourceTypeId ,IsResourceRef FROM dbo.ResourceReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt + WHERE HistoryTransactionId IS NULL UNION ALL SELECT ResourceTypeId ,ResourceSurrogateId @@ -2036,3 +2280,1004 @@ BEGIN CATCH THROW END CATCH GO +ALTER PROCEDURE dbo.UpdateResourceSearchParams + @FailedResources int = 0 OUT + ,@Resources dbo.ResourceList READONLY -- TODO: Remove after deployment + ,@ResourcesLake dbo.ResourceListLake READONLY + ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY + ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY + ,@TokenSearchParams dbo.TokenSearchParamList READONLY + ,@TokenTexts dbo.TokenTextList READONLY + ,@StringSearchParams dbo.StringSearchParamList READONLY + ,@UriSearchParams dbo.UriSearchParamList READONLY + ,@NumberSearchParams dbo.NumberSearchParamList READONLY + ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY + ,@DateTimeSearchParams dbo.DateTimeSearchParamList READONLY + ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY + ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY + ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY + ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY + ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY + ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = object_name(@@procid) + ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),'Input=Empty') + ,@ResourceRows int + ,@InsertRows int + ,@DeletedIdMap int + ,@FirstIdInt bigint + ,@CurrentRows int + +RetryResourceIdIntMapLogic: +BEGIN TRY + DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) + DECLARE @CurrentRefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @CurrentRefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + DECLARE @InputRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertRefIds AS TABLE (ResourceTypeId smallint NOT NULL, IdIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ReferenceSearchParamsWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,ReferenceResourceVersion int NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) + ) + + -- Prepare insert into ResourceIdIntMap outside of transaction to minimize blocking + INSERT INTO @InputRefIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL + + INSERT INTO @ExistingRefIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputRefIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + + INSERT INTO @InsertRefIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputRefIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingRefIds B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @InsertRows = (SELECT count(*) FROM @InsertRefIds) + IF @InsertRows > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @InsertRows, @FirstIdInt OUT + + INSERT INTO @InsertedRefIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertRefIds + END + + INSERT INTO @ReferenceSearchParamsWithIds + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), ReferenceResourceVersion + FROM @ReferenceSearchParams A + LEFT OUTER JOIN @InsertedRefIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingRefIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + + BEGIN TRANSACTION + + -- Update the search parameter hash value in the main resource table + IF EXISTS (SELECT * FROM @ResourcesLake) + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash FROM @ResourcesLake A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @ResourcesLake A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 + ELSE + UPDATE B + SET SearchParamHash = (SELECT SearchParamHash FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM dbo.Resource B + WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) + AND B.IsHistory = 0 + SET @ResourceRows = @@rowcount + + -- First, delete all the search params of the resources to reindex. + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + FROM @Ids A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + -- Next, insert all the new search params. + INSERT INTO dbo.ResourceWriteClaim + ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) + SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue + FROM @ResourceWriteClaims + + -- start delete logic from ResourceIdIntMap + INSERT INTO @CurrentRefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @CurrentRefIdsRaw + SET @CurrentRows = @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove not reused + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM @ReferenceSearchParamsWithIds B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced by resources + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced by reference search params + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- finally delete from id map + DELETE FROM B FROM @CurrentRefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedRefIds + + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM @ReferenceSearchParamsWithIds + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL + + INSERT INTO dbo.TokenSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow + FROM @TokenSearchParams + + INSERT INTO dbo.TokenText + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text + FROM @TokenTexts + + INSERT INTO dbo.StringSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax + FROM @StringSearchParams + + INSERT INTO dbo.UriSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri + FROM @UriSearchParams + + INSERT INTO dbo.NumberSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue + FROM @NumberSearchParams + + INSERT INTO dbo.QuantitySearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue + FROM @QuantitySearchParams + + INSERT INTO dbo.DateTimeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax + FROM @DateTimeSearchParams + + INSERT INTO dbo.ReferenceTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams + + INSERT INTO dbo.TokenTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 + FROM @TokenTokenCompositeSearchParams + + INSERT INTO dbo.TokenDateTimeCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams + + INSERT INTO dbo.TokenQuantityCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 + FROM @TokenQuantityCompositeSearchParams + + INSERT INTO dbo.TokenStringCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 + FROM @TokenStringCompositeSearchParams + + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange + FROM @TokenNumberNumberCompositeSearchParams + + COMMIT TRANSACTION + + SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @ResourceRows + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@ResourceRows,@Text=@DeletedIdMap +END TRY +BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation + OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @Ids + DELETE FROM @InputRefIds + DELETE FROM @CurrentRefIdsRaw + DELETE FROM @CurrentRefIds + DELETE FROM @ExistingRefIds + DELETE FROM @InsertRefIds + DELETE FROM @InsertedRefIds + DELETE FROM @ReferenceSearchParamsWithIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + THROW +END CATCH +GO +ALTER PROCEDURE dbo.HardDeleteResource + @ResourceTypeId smallint + ,@ResourceId varchar(64) + ,@KeepCurrentVersion bit + ,@IsResourceChangeCaptureEnabled bit = 1 -- TODO: Remove input parameter after deployment +AS +set nocount on +DECLARE @SP varchar(100) = object_name(@@procid) + ,@Mode varchar(200) = ' RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) + ,@st datetime = getUTCdate() + ,@TransactionId bigint + ,@DeletedIdMap int + ,@Rows int + +BEGIN TRY + EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT + SET @Mode = 'T='+convert(varchar,@TransactionId) + @Mode + + RetryResourceIdIntMapLogic: + + IF @KeepCurrentVersion = 0 + BEGIN TRANSACTION + + DECLARE @SurrogateIds TABLE (ResourceSurrogateId bigint NOT NULL) + + UPDATE dbo.Resource + SET IsDeleted = 1 + ,RawResource = 0xF -- invisible value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) + --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + + IF @KeepCurrentVersion = 0 + BEGIN + DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @RefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + + -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw + FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + INSERT INTO @RefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw + SET @Rows = @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM B FROM @RefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + END + + IF @@trancount > 0 COMMIT TRANSACTION + + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap +END TRY +BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() = 547 -- reference violation + BEGIN + DELETE FROM @SurrogateIds + DELETE FROM @RefIdsRaw + DELETE FROM @RefIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + THROW +END CATCH +GO +--DROP PROCEDURE dbo.MergeResources +GO +ALTER PROCEDURE dbo.MergeResources +-- This stored procedure can be used for: +-- 1. Ordinary put with single version per resource in input +-- 2. Put with history preservation (multiple input versions per resource) +-- 3. Copy from one gen2 store to another with ResourceSurrogateId preserved. + @AffectedRows int = 0 OUT + ,@RaiseExceptionOnConflict bit = 1 + ,@IsResourceChangeCaptureEnabled bit = 0 + ,@TransactionId bigint = NULL + ,@SingleTransaction bit = 1 + ,@Resources dbo.ResourceList READONLY -- before lake code. TODO: Remove after deployment + ,@ResourcesLake dbo.ResourceListLake READONLY -- Lake code + ,@ResourceWriteClaims dbo.ResourceWriteClaimList READONLY + ,@ReferenceSearchParams dbo.ReferenceSearchParamList READONLY + ,@TokenSearchParams dbo.TokenSearchParamList READONLY + ,@TokenTexts dbo.TokenTextList READONLY + ,@StringSearchParams dbo.StringSearchParamList READONLY + ,@UriSearchParams dbo.UriSearchParamList READONLY + ,@NumberSearchParams dbo.NumberSearchParamList READONLY + ,@QuantitySearchParams dbo.QuantitySearchParamList READONLY + ,@DateTimeSearchParms dbo.DateTimeSearchParamList READONLY + ,@ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY + ,@TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY + ,@TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY + ,@TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY + ,@TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY + ,@TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = object_name(@@procid) + ,@DummyTop bigint = 9223372036854775807 + ,@InitialTranCount int = @@trancount + ,@IsRetry bit = 0 + ,@RT smallint + ,@NewIdsCount int + ,@FirstIdInt bigint + ,@CurrentRows int + ,@DeletedIdMap int + +DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),'Input=Empty') +SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') + +SET @AffectedRows = 0 + +RetryResourceIdIntMapLogic: +BEGIN TRY + DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @CurrentRefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @CurrentRefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + DECLARE @ExistingIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertIds AS TABLE (ResourceTypeId smallint NOT NULL, IdIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ResourcesWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,HasVersionToCompare bit NOT NULL -- in case of multiple versions per resource indicates that row contains (existing version + 1) value + ,IsDeleted bit NOT NULL + ,IsHistory bit NOT NULL + ,KeepHistory bit NOT NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,RequestMethod varchar(10) NULL + ,SearchParamHash varchar(64) NULL + ,FileId bigint NULL + ,OffsetInFile int NULL + + PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) + ,UNIQUE (ResourceTypeId, ResourceIdInt, Version) + ) + DECLARE @ReferenceSearchParamsWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) + ) + + -- Prepare id map for reference search params Start --------------------------------------------------------------------------- + INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL + + INSERT INTO @ExistingIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsReference B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO @InsertedIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + INSERT INTO @ReferenceSearchParamsWithIds + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) + FROM @ReferenceSearchParams A + LEFT OUTER JOIN @InsertedIdsReference B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingIdsReference C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + -- Prepare id map for reference search params End --------------------------------------------------------------------------- + + -- Prepare id map for resources Start --------------------------------------------------------------------------- + DELETE FROM @InputIds + IF EXISTS (SELECT * FROM @ResourcesLake) + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @ResourcesLake GROUP BY ResourceTypeId, ResourceId + ELSE + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @Resources GROUP BY ResourceTypeId, ResourceId + + INSERT INTO @ExistingIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), A.ResourceId + FROM @InputIds A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @InsertedIdsReference C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + WHERE C.ResourceIdInt IS NOT NULL OR B.ResourceIdInt IS NOT NULL + + DELETE FROM @InsertIds + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsResource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO @InsertedIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + IF EXISTS (SELECT * FROM @ResourcesLake) + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile + FROM @ResourcesLake A + LEFT OUTER JOIN @InsertedIdsResource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIdsResource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + ELSE + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL + FROM @Resources A + LEFT OUTER JOIN @InsertedIdsResource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIdsResource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + -- Prepare id map for resources End --------------------------------------------------------------------------- + + DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) + + DECLARE @ResourceInfos AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,SurrogateId bigint NOT NULL + ,Version int NOT NULL + ,KeepHistory bit NOT NULL + ,PreviousVersion int NULL + ,PreviousSurrogateId bigint NULL + + PRIMARY KEY (ResourceTypeId, SurrogateId) + ) + + DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) + + IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 + SET @SingleTransaction = 1 + + SET @Mode += ' ST='+convert(varchar,@SingleTransaction) + + -- perform retry check in transaction to hold locks + IF @InitialTranCount = 0 + BEGIN + IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them + FROM @ResourcesWithIds A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0 + ) + BEGIN + BEGIN TRANSACTION + + INSERT INTO @Existing + ( ResourceTypeId, SurrogateId ) + SELECT B.ResourceTypeId, B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds) A + JOIN dbo.Resource B WITH (ROWLOCK, HOLDLOCK) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0 + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + IF @@rowcount = (SELECT count(*) FROM @ResourcesWithIds) SET @IsRetry = 1 + + IF @IsRetry = 0 COMMIT TRANSACTION -- commit check transaction + END + END + + SET @Mode += ' R='+convert(varchar,@IsRetry) + + IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION + + IF @IsRetry = 0 + BEGIN + INSERT INTO @ResourceInfos + ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) + SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds WHERE HasVersionToCompare = 1) A + LEFT OUTER JOIN dbo.CurrentResources B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. + ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + + IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <= PreviousVersion) + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 + + INSERT INTO @PreviousSurrogateIds + SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory + FROM @ResourceInfos + WHERE PreviousSurrogateId IS NOT NULL + + IF @@rowcount > 0 + BEGIN + UPDATE dbo.Resource + SET IsHistory = 1 + WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) + SET @AffectedRows += @@rowcount + + IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) + UPDATE dbo.Resource + SET IsHistory = 1 + ,RawResource = 0xF -- "invisible" value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) + ELSE + DELETE FROM dbo.Resource WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0) + SET @AffectedRows += @@rowcount + + DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.ResourceReferenceSearchParams + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @CurrentRows = @@rowcount + SET @AffectedRows += @CurrentRows + -- start deleting from ResourceIdIntMap + INSERT INTO @CurrentRefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @CurrentRefIdsRaw + SET @CurrentRows = @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove not reused + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM @ReferenceSearchParamsWithIds B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced in Resources + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove still referenced in ResourceReferenceSearchParams + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- delete from id map + DELETE FROM B FROM @CurrentRefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END + DELETE FROM dbo.StringReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenText WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.StringSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.UriSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.NumberSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.QuantitySearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.DateTimeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.ReferenceTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenTokenCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenDateTimeCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenQuantityCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenStringCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @AffectedRows += @@rowcount + + --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' + END + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsResource + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsReference + + INSERT INTO dbo.Resource + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, FileId, OffsetInFile + FROM @ResourcesWithIds + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ResourceWriteClaim + ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) + SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue + FROM @ResourceWriteClaims + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM @ReferenceSearchParamsWithIds + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NULL + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow + FROM @TokenSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenText + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text + FROM @TokenTexts + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax + FROM @StringSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.UriSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri + FROM @UriSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.NumberSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue + FROM @NumberSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.QuantitySearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue + FROM @QuantitySearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.DateTimeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax + FROM @DateTimeSearchParms + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ReferenceTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 + FROM @TokenTokenCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenDateTimeCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenQuantityCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 + FROM @TokenQuantityCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenStringCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 + FROM @TokenStringCompositeSearchParams + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange + FROM @TokenNumberNumberCompositeSearchParams + SET @AffectedRows += @@rowcount + END -- @IsRetry = 0 + ELSE + BEGIN -- @IsRetry = 1 + INSERT INTO dbo.ResourceWriteClaim + ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) + SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue + FROM (SELECT TOP (@DummyTop) * FROM @ResourceWriteClaims) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.ResourceWriteClaim C WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParamsWithIds) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NULL) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.StringReferenceSearchParams C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow + FROM (SELECT TOP (@DummyTop) * FROM @TokenSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenText + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text + FROM (SELECT TOP (@DummyTop) * FROM @TokenTexts) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.StringSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax + FROM (SELECT TOP (@DummyTop) * FROM @StringSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenText C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.UriSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri + FROM (SELECT TOP (@DummyTop) * FROM @UriSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.UriSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.NumberSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue + FROM (SELECT TOP (@DummyTop) * FROM @NumberSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.NumberSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.QuantitySearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue + FROM (SELECT TOP (@DummyTop) * FROM @QuantitySearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.QuantitySearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.DateTimeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax + FROM (SELECT TOP (@DummyTop) * FROM @DateTimeSearchParms) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.ReferenceTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * FROM @ReferenceTokenCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.DateTimeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenTokenCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenTokenCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenTokenCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenDateTimeCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenDateTimeCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenDateTimeCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenQuantityCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenQuantityCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenQuantityCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenStringCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2 + FROM (SELECT TOP (@DummyTop) * FROM @TokenStringCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenStringCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange + FROM (SELECT TOP (@DummyTop) * FROM @TokenNumberNumberCompositeSearchParams) A + WHERE EXISTS (SELECT * FROM @Existing B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * FROM dbo.TokenNumberNumberCompositeSearchParam C WHERE C.ResourceTypeId = A.ResourceTypeId AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + SET @AffectedRows += @@rowcount + END + + IF @IsResourceChangeCaptureEnabled = 1 --If the resource change capture feature is enabled, to execute a stored procedure called CaptureResourceChanges to insert resource change data. + EXECUTE dbo.CaptureResourceIdsForChanges @Resources, @ResourcesLake + + IF @TransactionId IS NOT NULL + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + + IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows,@Text=@DeletedIdMap +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation + OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @ResourcesWithIds + DELETE FROM @ReferenceSearchParamsWithIds + DELETE FROM @CurrentRefIdsRaw + DELETE FROM @CurrentRefIds + DELETE FROM @InputIds + DELETE FROM @InsertIds + DELETE FROM @InsertedIdsReference + DELETE FROM @ExistingIdsReference + DELETE FROM @InsertedIdsResource + DELETE FROM @ExistingIdsResource + DELETE FROM @Existing + DELETE FROM @ResourceInfos + DELETE FROM @PreviousSurrogateIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW +END CATCH +GO +--DROP TABLE IF EXISTS ResourceTbl -- TODO: Remove table after deployment +GO +--DROP TABLE IF EXISTS ReferenceSearchParamTbl -- TODO: Remove table after deployment +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 52da069943..5f51d22ccd 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -162,6 +162,7 @@ CREATE TYPE dbo.ResourceListLake AS TABLE ( IsRawResourceMetaSet BIT NOT NULL, RequestMethod VARCHAR (10) NULL, SearchParamHash VARCHAR (64) NULL, + FileId BIGINT NULL, OffsetInFile INT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), UNIQUE (ResourceTypeId, ResourceId, Version)); @@ -3438,13 +3439,14 @@ END CATCH GO CREATE PROCEDURE dbo.HardDeleteResource -@ResourceTypeId SMALLINT, @ResourceId VARCHAR (64), @KeepCurrentVersion BIT, @IsResourceChangeCaptureEnabled BIT +@ResourceTypeId SMALLINT, @ResourceId VARCHAR (64), @KeepCurrentVersion BIT, @IsResourceChangeCaptureEnabled BIT=1 AS SET NOCOUNT ON; -DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'RT=' + CONVERT (VARCHAR, @ResourceTypeId) + ' R=' + @ResourceId + ' V=' + CONVERT (VARCHAR, @KeepCurrentVersion) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled), @st AS DATETIME = getUTCdate(), @TransactionId AS BIGINT; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = ' RT=' + CONVERT (VARCHAR, @ResourceTypeId) + ' R=' + @ResourceId + ' V=' + CONVERT (VARCHAR, @KeepCurrentVersion), @st AS DATETIME = getUTCdate(), @TransactionId AS BIGINT, @DeletedIdMap AS INT, @Rows AS INT; +EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUTPUT; +SET @Mode = 'T=' + CONVERT (VARCHAR, @TransactionId) + @Mode; +RetryResourceIdIntMapLogic: BEGIN TRY - IF @IsResourceChangeCaptureEnabled = 1 - EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUTPUT; IF @KeepCurrentVersion = 0 BEGIN TRANSACTION; DECLARE @SurrogateIds TABLE ( @@ -3461,16 +3463,67 @@ BEGIN TRY OR IsHistory = 1); IF @KeepCurrentVersion = 0 BEGIN + DECLARE @RefIdsRaw TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL); + DECLARE @RefIds TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)); DELETE B FROM @SurrogateIds AS A INNER LOOP JOIN dbo.ResourceWriteClaim AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); - DELETE dbo.ReferenceSearchParam - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId IN (SELECT ResourceSurrogateId - FROM @SurrogateIds); + DELETE B + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ResourceReferenceSearchParams AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + INSERT INTO @RefIds + SELECT DISTINCT ResourceTypeId, + ResourceIdInt + FROM @RefIdsRaw; + SET @Rows = @@rowcount; + IF @Rows > 0 + BEGIN + DELETE A + FROM @RefIds AS A + WHERE EXISTS (SELECT * + FROM dbo.CurrentResources AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt); + SET @Rows -= @@rowcount; + IF @Rows > 0 + BEGIN + DELETE A + FROM @RefIds AS A + WHERE EXISTS (SELECT * + FROM dbo.ResourceReferenceSearchParams AS B + WHERE B.ReferenceResourceTypeId = A.ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + SET @Rows -= @@rowcount; + IF @Rows > 0 + BEGIN + DELETE B + FROM @RefIds AS A + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt; + SET @DeletedIdMap = @@rowcount; + END + END + END + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.StringReferenceSearchParams AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); DELETE B FROM @SurrogateIds AS A INNER LOOP JOIN @@ -3565,15 +3618,23 @@ BEGIN TRY END IF @@trancount > 0 COMMIT TRANSACTION; - IF @IsResourceChangeCaptureEnabled = 1 - EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = @DeletedIdMap; END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; - THROW; + IF error_number() = 547 + AND error_message() LIKE '%DELETE%' + BEGIN + DELETE @SurrogateIds; + DELETE @RefIdsRaw; + DELETE @RefIds; + GOTO RetryResourceIdIntMapLogic; + END + ELSE + THROW; END CATCH GO @@ -3658,7 +3719,7 @@ CREATE PROCEDURE dbo.MergeResources @AffectedRows INT=0 OUTPUT, @RaiseExceptionOnConflict BIT=1, @IsResourceChangeCaptureEnabled BIT=0, @TransactionId BIGINT=NULL, @SingleTransaction BIT=1, @Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParms dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY AS SET NOCOUNT ON; -DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0, @RT AS SMALLINT, @NewIdsCount AS INT, @FirstIdInt AS BIGINT; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0, @RT AS SMALLINT, @NewIdsCount AS INT, @FirstIdInt AS BIGINT, @CurrentRows AS INT, @DeletedIdMap AS INT; DECLARE @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, @@ -3671,21 +3732,34 @@ DECLARE @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(R FROM @ResourcesLake) AS A), 'Input=Empty'); SET @Mode += ' E=' + CONVERT (VARCHAR, @RaiseExceptionOnConflict) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled) + ' IT=' + CONVERT (VARCHAR, @InitialTranCount) + ' T=' + isnull(CONVERT (VARCHAR, @TransactionId), 'NULL'); SET @AffectedRows = 0; -RetryResourceIdIntMapInsert: +RetryResourceIdIntMapLogic: BEGIN TRY - DECLARE @RTs AS TABLE ( - ResourceTypeId SMALLINT NOT NULL PRIMARY KEY); DECLARE @InputIds AS TABLE ( ResourceTypeId SMALLINT NOT NULL, ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); - DECLARE @ExistingIds AS TABLE ( + DECLARE @CurrentRefIdsRaw TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL); + DECLARE @CurrentRefIds TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)); + DECLARE @ExistingIdsReference AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @ExistingIdsResource AS TABLE ( ResourceTypeId SMALLINT NOT NULL, ResourceIdInt BIGINT NOT NULL, ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); DECLARE @InsertIds AS TABLE ( - ResourceIndex INT NOT NULL, - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL); - DECLARE @InsertedIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + IdIndex INT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @InsertedIdsReference AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @InsertedIdsResource AS TABLE ( ResourceTypeId SMALLINT NOT NULL, ResourceIdInt BIGINT NOT NULL, ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); @@ -3718,50 +3792,34 @@ BEGIN TRY ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL; - INSERT INTO @RTs - SELECT DISTINCT ResourceTypeId - FROM @InputIds; - WHILE EXISTS (SELECT * - FROM @RTs) + INSERT INTO @ExistingIdsReference (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT A.ResourceTypeId, + ResourceIdInt, + A.ResourceId + FROM @InputIds AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId; + INSERT INTO @InsertIds (ResourceTypeId, IdIndex, ResourceId) + SELECT ResourceTypeId, + row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, + ResourceId + FROM @InputIds AS A + WHERE NOT EXISTS (SELECT * + FROM @ExistingIdsReference AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId); + SET @NewIdsCount = (SELECT count(*) + FROM @InsertIds); + IF @NewIdsCount > 0 BEGIN - SET @RT = (SELECT TOP 1 ResourceTypeId - FROM @RTs); - INSERT INTO @ExistingIds (ResourceTypeId, ResourceIdInt, ResourceId) - SELECT @RT, - ResourceIdInt, - A.ResourceId - FROM (SELECT * - FROM @InputIds - WHERE ResourceTypeId = @RT) AS A - INNER JOIN - dbo.ResourceIdIntMap AS B - ON B.ResourceTypeId = @RT - AND B.ResourceId = A.ResourceId; - DELETE @InsertIds; - INSERT INTO @InsertIds (ResourceIndex, ResourceId) - SELECT row_number() OVER (ORDER BY ResourceId) - 1 AS RowId, + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; + INSERT INTO @InsertedIdsReference (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT ResourceTypeId, + IdIndex + @FirstIdInt, ResourceId - FROM (SELECT ResourceId - FROM @InputIds - WHERE ResourceTypeId = @RT) AS A - WHERE NOT EXISTS (SELECT * - FROM @ExistingIds AS B - WHERE B.ResourceTypeId = @RT - AND B.ResourceId = A.ResourceId); - SET @NewIdsCount = (SELECT count(*) - FROM @InsertIds); - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; - INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) - OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @RT, - ResourceIndex + @FirstIdInt, - ResourceId - FROM @InsertIds; - END - DELETE @RTs - WHERE ResourceTypeId = @RT; + FROM @InsertIds; END INSERT INTO @ReferenceSearchParamsWithIds (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) SELECT A.ResourceTypeId, @@ -3770,155 +3828,118 @@ BEGIN TRY BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt, B.ResourceIdInt) - FROM (SELECT * - FROM @ReferenceSearchParams - WHERE ReferenceResourceTypeId IS NOT NULL) AS A + FROM @ReferenceSearchParams AS A LEFT OUTER JOIN - @InsertedIds AS B + @InsertedIdsReference AS B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId LEFT OUTER JOIN - @ExistingIds AS C + @ExistingIdsReference AS C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId; DELETE @InputIds; - DELETE @RTs; - DELETE @InsertedIds; - DELETE @ExistingIds; - INSERT INTO @InputIds - SELECT ResourceTypeId, - ResourceId - FROM (SELECT ResourceTypeId, - ResourceId - FROM @ResourcesLake - UNION ALL - SELECT ResourceTypeId, - ResourceId - FROM @Resources) AS A - GROUP BY ResourceTypeId, ResourceId; - INSERT INTO @RTs - SELECT DISTINCT ResourceTypeId - FROM @InputIds; - WHILE EXISTS (SELECT * - FROM @RTs) - BEGIN - SET @RT = (SELECT TOP 1 ResourceTypeId - FROM @RTs); - INSERT INTO @ExistingIds (ResourceTypeId, ResourceIdInt, ResourceId) - SELECT @RT, - ResourceIdInt, - A.ResourceId - FROM (SELECT * - FROM @InputIds - WHERE ResourceTypeId = @RT) AS A - INNER JOIN - dbo.ResourceIdIntMap AS B - ON B.ResourceTypeId = @RT - AND B.ResourceId = A.ResourceId; - DELETE @InsertIds; - INSERT INTO @InsertIds (ResourceIndex, ResourceId) - SELECT row_number() OVER (ORDER BY ResourceId) - 1 AS RowId, - ResourceId - FROM (SELECT ResourceId - FROM @InputIds - WHERE ResourceTypeId = @RT) AS A - WHERE NOT EXISTS (SELECT * - FROM @ExistingIds AS B - WHERE B.ResourceTypeId = @RT - AND B.ResourceId = A.ResourceId); - SET @NewIdsCount = (SELECT count(*) - FROM @InsertIds); - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; - INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) - OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @RT, - ResourceIndex + @FirstIdInt, - ResourceId - FROM @InsertIds; - END - DELETE @RTs - WHERE ResourceTypeId = @RT; - END - INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile) + IF EXISTS (SELECT * + FROM @ResourcesLake) + INSERT INTO @InputIds + SELECT ResourceTypeId, + ResourceId + FROM @ResourcesLake + GROUP BY ResourceTypeId, ResourceId; + ELSE + INSERT INTO @InputIds + SELECT ResourceTypeId, + ResourceId + FROM @Resources + GROUP BY ResourceTypeId, ResourceId; + INSERT INTO @ExistingIdsResource (ResourceTypeId, ResourceIdInt, ResourceId) SELECT A.ResourceTypeId, - A.ResourceId, isnull(C.ResourceIdInt, B.ResourceIdInt), - Version, - HasVersionToCompare, - IsHistory, - ResourceSurrogateId, - IsDeleted, - RequestMethod, - KeepHistory, - RawResource, - IsRawResourceMetaSet, - SearchParamHash, - FileId, - OffsetInFile - FROM (SELECT ResourceTypeId, - ResourceId, - Version, - HasVersionToCompare, - IsHistory, - ResourceSurrogateId, - IsDeleted, - RequestMethod, - KeepHistory, - RawResource, - IsRawResourceMetaSet, - SearchParamHash, - CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END AS FileId, - OffsetInFile - FROM @ResourcesLake - UNION ALL - SELECT ResourceTypeId, - ResourceId, - Version, - HasVersionToCompare, - IsHistory, - ResourceSurrogateId, - IsDeleted, - RequestMethod, - KeepHistory, - RawResource, - IsRawResourceMetaSet, - SearchParamHash, - NULL, - NULL - FROM @Resources) AS A + A.ResourceId + FROM @InputIds AS A LEFT OUTER JOIN - @InsertedIds AS B + dbo.ResourceIdIntMap AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId LEFT OUTER JOIN - @ExistingIds AS C + @InsertedIdsReference AS C ON C.ResourceTypeId = A.ResourceTypeId - AND C.ResourceId = A.ResourceId; -END TRY -BEGIN CATCH - IF @InitialTranCount = 0 - AND @@trancount > 0 - ROLLBACK; - IF error_number() = 1750 - THROW; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; - IF error_number() IN (2601, 2627) - AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' + AND C.ResourceId = A.ResourceId + WHERE C.ResourceIdInt IS NOT NULL + OR B.ResourceIdInt IS NOT NULL; + DELETE @InsertIds; + INSERT INTO @InsertIds (ResourceTypeId, IdIndex, ResourceId) + SELECT ResourceTypeId, + row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, + ResourceId + FROM @InputIds AS A + WHERE NOT EXISTS (SELECT * + FROM @ExistingIdsResource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId); + SET @NewIdsCount = (SELECT count(*) + FROM @InsertIds); + IF @NewIdsCount > 0 BEGIN - DELETE @ResourcesWithIds; - DELETE @ReferenceSearchParamsWithIds; - DELETE @InputIds; - DELETE @RTs; - DELETE @InsertedIds; - DELETE @ExistingIds; - GOTO RetryResourceIdIntMapInsert; + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUTPUT; + INSERT INTO @InsertedIdsResource (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT ResourceTypeId, + IdIndex + @FirstIdInt, + ResourceId + FROM @InsertIds; END + IF EXISTS (SELECT * + FROM @ResourcesLake) + INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile) + SELECT A.ResourceTypeId, + A.ResourceId, + isnull(C.ResourceIdInt, B.ResourceIdInt), + Version, + HasVersionToCompare, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + KeepHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + FileId, + OffsetInFile + FROM @ResourcesLake AS A + LEFT OUTER JOIN + @InsertedIdsResource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN + @ExistingIdsResource AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceId = A.ResourceId; ELSE - THROW; -END CATCH -BEGIN TRY + INSERT INTO @ResourcesWithIds (ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile) + SELECT A.ResourceTypeId, + A.ResourceId, + isnull(C.ResourceIdInt, B.ResourceIdInt), + Version, + HasVersionToCompare, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + KeepHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + NULL, + NULL + FROM @Resources AS A + LEFT OUTER JOIN + @InsertedIdsResource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN + @ExistingIdsResource AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceId = A.ResourceId; DECLARE @Existing AS TABLE ( ResourceTypeId SMALLINT NOT NULL, SurrogateId BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)); @@ -4041,7 +4062,60 @@ BEGIN TRY FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; - DELETE dbo.ReferenceSearchParam + DELETE dbo.ResourceReferenceSearchParams + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @CurrentRows = @@rowcount; + SET @AffectedRows += @CurrentRows; + INSERT INTO @CurrentRefIds + SELECT DISTINCT ResourceTypeId, + ResourceIdInt + FROM @CurrentRefIdsRaw; + SET @CurrentRows = @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE A + FROM @CurrentRefIds AS A + WHERE EXISTS (SELECT * + FROM @ReferenceSearchParamsWithIds AS B + WHERE B.ReferenceResourceTypeId = A.ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + SET @CurrentRows -= @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE A + FROM @CurrentRefIds AS A + WHERE EXISTS (SELECT * + FROM dbo.CurrentResources AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt); + SET @CurrentRows -= @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE A + FROM @CurrentRefIds AS A + WHERE EXISTS (SELECT * + FROM dbo.ResourceReferenceSearchParams AS B + WHERE B.ReferenceResourceTypeId = A.ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + SET @CurrentRows -= @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE B + FROM @CurrentRefIds AS A + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt; + SET @DeletedIdMap = @@rowcount; + END + END + END + END + DELETE dbo.StringReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId @@ -4126,6 +4200,16 @@ BEGIN TRY AND SurrogateId = ResourceSurrogateId); SET @AffectedRows += @@rowcount; END + INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT ResourceTypeId, + ResourceIdInt, + ResourceId + FROM @InsertedIdsResource; + INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT ResourceTypeId, + ResourceIdInt, + ResourceId + FROM @InsertedIdsReference; INSERT INTO dbo.Resource (ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile) SELECT ResourceTypeId, ResourceIdInt, @@ -4643,7 +4727,7 @@ BEGIN TRY IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows, @Text = @DeletedIdMap; END TRY BEGIN CATCH IF @InitialTranCount = 0 @@ -4652,15 +4736,36 @@ BEGIN CATCH IF error_number() = 1750 THROW; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; - IF @RaiseExceptionOnConflict = 1 - AND error_number() IN (2601, 2627) - AND (error_message() LIKE '%''dbo.Resource%' - OR error_message() LIKE '%''dbo.CurrentResources%' - OR error_message() LIKE '%''dbo.HistoryResources%' - OR error_message() LIKE '%''dbo.RawResources''%') - THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + IF error_number() IN (2601, 2627) + AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' + OR error_number() = 547 + AND error_message() LIKE '%DELETE%' + BEGIN + DELETE @ResourcesWithIds; + DELETE @ReferenceSearchParamsWithIds; + DELETE @CurrentRefIdsRaw; + DELETE @CurrentRefIds; + DELETE @InputIds; + DELETE @InsertIds; + DELETE @InsertedIdsReference; + DELETE @ExistingIdsReference; + DELETE @InsertedIdsResource; + DELETE @ExistingIdsResource; + DELETE @Existing; + DELETE @ResourceInfos; + DELETE @PreviousSurrogateIds; + GOTO RetryResourceIdIntMapLogic; + END ELSE - THROW; + IF @RaiseExceptionOnConflict = 1 + AND error_number() IN (2601, 2627) + AND (error_message() LIKE '%''dbo.Resource%' + OR error_message() LIKE '%''dbo.CurrentResources%' + OR error_message() LIKE '%''dbo.HistoryResources%' + OR error_message() LIKE '%''dbo.RawResources''%') + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW; END CATCH GO @@ -4791,14 +4896,56 @@ CREATE PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId BIGINT, @AffectedRows INT=NULL OUTPUT AS SET NOCOUNT ON; -DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(), @TypeId AS SMALLINT; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME, @Rows AS INT, @DeletedIdMap AS INT; SET @AffectedRows = 0; +Retry: BEGIN TRY - DELETE dbo.Resource - WHERE HistoryTransactionId = @TransactionId - AND RawResource = 0xF; - SET @AffectedRows += @@rowcount; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Start = @st, @Rows = @AffectedRows; + DECLARE @Ids TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL); + BEGIN TRANSACTION; + SET @st = getUTCdate(); + DELETE A + OUTPUT deleted.ResourceTypeId, deleted.ResourceIdInt INTO @Ids + FROM dbo.Resource AS A + WHERE HistoryTransactionId = @TransactionId; + SET @Rows = @@rowcount; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Start = @st, @Rows = @Rows; + SET @AffectedRows += @Rows; + SET @st = getUTCdate(); + IF @Rows > 0 + BEGIN + DELETE A + FROM @Ids AS A + WHERE EXISTS (SELECT * + FROM dbo.CurrentResources AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt); + SET @Rows -= @@rowcount; + IF @Rows > 0 + BEGIN + DELETE A + FROM @Ids AS A + WHERE EXISTS (SELECT * + FROM dbo.ResourceReferenceSearchParams AS B + WHERE B.ReferenceResourceTypeId = A.ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + SET @Rows -= @@rowcount; + IF @Rows > 0 + BEGIN + DELETE B + FROM @Ids AS A + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt; + SET @DeletedIdMap = @@rowcount; + END + END + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'ResourceIdIntMap', @Action = 'Delete', @Start = @st, @Rows = @DeletedIdMap; + COMMIT TRANSACTION; + SET @st = getUTCdate(); UPDATE dbo.Resource SET TransactionId = NULL WHERE TransactionId = @TransactionId; @@ -4807,8 +4954,17 @@ END TRY BEGIN CATCH IF error_number() = 1750 THROW; + IF @@trancount > 0 + ROLLBACK; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; - THROW; + IF error_number() = 547 + AND error_message() LIKE '%DELETE%' + BEGIN + DELETE @Ids; + GOTO Retry; + END + ELSE + THROW; END CATCH GO @@ -5422,11 +5578,92 @@ DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@pro SELECT ResourceTypeId, ResourceSurrogateId, Version - FROM @Resources) AS A), 'Input=Empty'), @Rows AS INT; + FROM @Resources) AS A), 'Input=Empty'), @ResourceRows AS INT, @InsertRows AS INT, @DeletedIdMap AS INT, @FirstIdInt AS BIGINT, @CurrentRows AS INT; +RetryResourceIdIntMapLogic: BEGIN TRY DECLARE @Ids TABLE ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL); + DECLARE @CurrentRefIdsRaw TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL); + DECLARE @CurrentRefIds TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)); + DECLARE @InputRefIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @ExistingRefIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @InsertRefIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + IdIndex INT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @InsertedRefIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)); + DECLARE @ReferenceSearchParamsWithIds AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceIdInt BIGINT NOT NULL, + ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt)); + INSERT INTO @InputRefIds + SELECT DISTINCT ReferenceResourceTypeId, + ReferenceResourceId + FROM @ReferenceSearchParams + WHERE ReferenceResourceTypeId IS NOT NULL; + INSERT INTO @ExistingRefIds (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT A.ResourceTypeId, + ResourceIdInt, + A.ResourceId + FROM @InputRefIds AS A + INNER JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId; + INSERT INTO @InsertRefIds (ResourceTypeId, IdIndex, ResourceId) + SELECT ResourceTypeId, + row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, + ResourceId + FROM @InputRefIds AS A + WHERE NOT EXISTS (SELECT * + FROM @ExistingRefIds AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId); + SET @InsertRows = (SELECT count(*) + FROM @InsertRefIds); + IF @InsertRows > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @InsertRows, @FirstIdInt OUTPUT; + INSERT INTO @InsertedRefIds (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT ResourceTypeId, + IdIndex + @FirstIdInt, + ResourceId + FROM @InsertRefIds; + END + INSERT INTO @ReferenceSearchParamsWithIds (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion) + SELECT A.ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + isnull(C.ResourceIdInt, B.ResourceIdInt), + ReferenceResourceVersion + FROM @ReferenceSearchParams AS A + LEFT OUTER JOIN + @InsertedRefIds AS B + ON B.ResourceTypeId = A.ReferenceResourceTypeId + AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN + @ExistingRefIds AS C + ON C.ResourceTypeId = A.ReferenceResourceTypeId + AND C.ResourceId = A.ReferenceResourceId; BEGIN TRANSACTION; IF EXISTS (SELECT * FROM @ResourcesLake) @@ -5455,99 +5692,100 @@ BEGIN TRY WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) AND B.IsHistory = 0; - SET @Rows = @@rowcount; + SET @ResourceRows = @@rowcount; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.ResourceWriteClaim AS B ON B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B - FROM dbo.ResourceReferenceSearchParams AS B - WHERE EXISTS (SELECT * - FROM @Ids AS A - WHERE A.ResourceTypeId = B.ResourceTypeId - AND A.ResourceSurrogateId = B.ResourceSurrogateId); + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + FROM @Ids AS A + INNER LOOP JOIN + dbo.ResourceReferenceSearchParams AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B - FROM dbo.StringReferenceSearchParams AS B - WHERE EXISTS (SELECT * - FROM @Ids AS A - WHERE A.ResourceTypeId = B.ResourceTypeId - AND A.ResourceSurrogateId = B.ResourceSurrogateId); + FROM @Ids AS A + INNER LOOP JOIN + dbo.StringReferenceSearchParams AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.TokenSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.TokenText AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.StringSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.UriSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.NumberSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.QuantitySearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.DateTimeSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.TokenStringCompositeSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; DELETE B FROM @Ids AS A - INNER JOIN + INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId; @@ -5556,18 +5794,64 @@ BEGIN TRY ClaimTypeId, ClaimValue FROM @ResourceWriteClaims; + INSERT INTO @CurrentRefIds + SELECT DISTINCT ResourceTypeId, + ResourceIdInt + FROM @CurrentRefIdsRaw; + SET @CurrentRows = @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE A + FROM @CurrentRefIds AS A + WHERE EXISTS (SELECT * + FROM @ReferenceSearchParamsWithIds AS B + WHERE B.ReferenceResourceTypeId = A.ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + SET @CurrentRows -= @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE A + FROM @CurrentRefIds AS A + WHERE EXISTS (SELECT * + FROM dbo.CurrentResources AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt); + SET @CurrentRows -= @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE A + FROM @CurrentRefIds AS A + WHERE EXISTS (SELECT * + FROM dbo.ResourceReferenceSearchParams AS B + WHERE B.ReferenceResourceTypeId = A.ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + SET @CurrentRows -= @@rowcount; + IF @CurrentRows > 0 + BEGIN + DELETE B + FROM @CurrentRefIds AS A + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt; + SET @DeletedIdMap = @@rowcount; + END + END + END + END + INSERT INTO dbo.ResourceIdIntMap (ResourceTypeId, ResourceIdInt, ResourceId) + SELECT ResourceTypeId, + ResourceIdInt, + ResourceId + FROM @InsertedRefIds; INSERT INTO dbo.ResourceReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) - SELECT A.ResourceTypeId, + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, - B.ResourceIdInt - FROM @ReferenceSearchParams AS A - INNER JOIN - dbo.ResourceIdIntMap AS B - ON B.ResourceTypeId = A.ReferenceResourceTypeId - AND B.ResourceId = A.ReferenceResourceId; + ReferenceResourceIdInt + FROM @ReferenceSearchParamsWithIds; INSERT INTO dbo.StringReferenceSearchParams (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId) SELECT ResourceTypeId, ResourceSurrogateId, @@ -5708,14 +5992,30 @@ BEGIN TRY COMMIT TRANSACTION; SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) - FROM @ResourcesLake) - @Rows; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; + FROM @ResourcesLake) - @ResourceRows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @ResourceRows, @Text = @DeletedIdMap; END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; - THROW; + IF error_number() IN (2601, 2627) + AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' + OR error_number() = 547 + AND error_message() LIKE '%DELETE%' + BEGIN + DELETE @Ids; + DELETE @InputRefIds; + DELETE @CurrentRefIdsRaw; + DELETE @CurrentRefIds; + DELETE @ExistingRefIds; + DELETE @InsertRefIds; + DELETE @InsertedRefIds; + DELETE @ReferenceSearchParamsWithIds; + GOTO RetryResourceIdIntMapLogic; + END + ELSE + THROW; END CATCH GO @@ -5773,28 +6073,6 @@ SELECT ResourceTypeId, IsResourceRef FROM dbo.StringReferenceSearchParams; - -GO -CREATE TRIGGER dbo.ReferenceSearchParamDel - ON dbo.ReferenceSearchParam - INSTEAD OF DELETE - AS BEGIN - DELETE A - FROM dbo.ResourceReferenceSearchParams AS A - WHERE EXISTS (SELECT * - FROM Deleted AS B - WHERE B.IsResourceRef = 1 - AND B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId); - DELETE A - FROM dbo.StringReferenceSearchParams AS A - WHERE EXISTS (SELECT * - FROM Deleted AS B - WHERE B.IsResourceRef = 0 - AND B.ResourceTypeId = A.ResourceTypeId - AND B.ResourceSurrogateId = A.ResourceSurrogateId); - END - GO CREATE VIEW dbo.Resource AS diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql index 52e82f0aa3..3ae86f6ad5 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql @@ -2,21 +2,25 @@ @ResourceTypeId smallint ,@ResourceId varchar(64) ,@KeepCurrentVersion bit - ,@IsResourceChangeCaptureEnabled bit + ,@IsResourceChangeCaptureEnabled bit = 1 -- TODO: Remove input parameter after deployment AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled) + ,@Mode varchar(200) = ' RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) ,@st datetime = getUTCdate() ,@TransactionId bigint + ,@DeletedIdMap int + ,@Rows int -BEGIN TRY - IF @IsResourceChangeCaptureEnabled = 1 EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT +EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT +SET @Mode = 'T='+convert(varchar,@TransactionId) + @Mode +RetryResourceIdIntMapLogic: +BEGIN TRY IF @KeepCurrentVersion = 0 BEGIN TRANSACTION - DECLARE @SurrogateIds TABLE (ResourceSurrogateId BIGINT NOT NULL) + DECLARE @SurrogateIds TABLE (ResourceSurrogateId bigint NOT NULL) UPDATE dbo.Resource SET IsDeleted = 1 @@ -31,9 +35,32 @@ BEGIN TRY IF @KeepCurrentVersion = 0 BEGIN + DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @RefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM dbo.ReferenceSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds) + DELETE FROM B + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw + FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + INSERT INTO @RefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw + SET @Rows = @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM B FROM @RefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) @@ -51,13 +78,23 @@ BEGIN TRY IF @@trancount > 0 COMMIT TRANSACTION - IF @IsResourceChangeCaptureEnabled = 1 EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - THROW + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() = 547 AND error_message() LIKE '%DELETE%'-- reference violation on DELETE + BEGIN + DELETE FROM @SurrogateIds + DELETE FROM @RefIdsRaw + DELETE FROM @RefIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + THROW END CATCH GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 8066e28317..0c670c5c80 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -37,19 +37,24 @@ DECLARE @st datetime = getUTCdate() ,@RT smallint ,@NewIdsCount int ,@FirstIdInt bigint + ,@CurrentRows int + ,@DeletedIdMap int DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),'Input=Empty') SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') SET @AffectedRows = 0 -RetryResourceIdIntMapInsert: +RetryResourceIdIntMapLogic: BEGIN TRY - DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) - DECLARE @ExistingIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) - DECLARE @InsertIds AS TABLE (ResourceIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL) - DECLARE @InsertedIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @CurrentRefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @CurrentRefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + DECLARE @ExistingIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertIds AS TABLE (ResourceTypeId smallint NOT NULL, IdIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) DECLARE @ResourcesWithIds AS TABLE ( ResourceTypeId smallint NOT NULL @@ -83,135 +88,89 @@ BEGIN TRY UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) ) + -- Prepare id map for reference search params Start --------------------------------------------------------------------------- INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL - INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds --- Prepare id map for reference search params Start --------------------------------------------------------------------------- - WHILE EXISTS (SELECT * FROM @RTs) - BEGIN - SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) - - INSERT INTO @ExistingIds - ( ResourceTypeId, ResourceIdInt, ResourceId ) - SELECT @RT, ResourceIdInt, A.ResourceId - FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId + INSERT INTO @ExistingIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - DELETE FROM @InsertIds - - INSERT INTO @InsertIds - ( ResourceIndex, ResourceId ) - SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId - FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A - WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) - - SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - - INSERT INTO dbo.ResourceIdIntMap - ( ResourceTypeId, ResourceIdInt, ResourceId ) - OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId - FROM @InsertIds - END + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsReference B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - DELETE FROM @RTs WHERE ResourceTypeId = @RT + INSERT INTO @InsertedIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds END INSERT INTO @ReferenceSearchParamsWithIds ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) - FROM (SELECT * FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL) A - LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId - LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId --- Prepare id map for reference search params End --------------------------------------------------------------------------- + FROM @ReferenceSearchParams A + LEFT OUTER JOIN @InsertedIdsReference B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingIdsReference C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + -- Prepare id map for reference search params End --------------------------------------------------------------------------- + -- Prepare id map for resources Start --------------------------------------------------------------------------- DELETE FROM @InputIds - DELETE FROM @RTs - DELETE FROM @InsertedIds - DELETE FROM @ExistingIds - --- Prepare id map for resources Start --------------------------------------------------------------------------- - INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId - FROM (SELECT ResourceTypeId, ResourceId FROM @ResourcesLake - UNION ALL - SELECT ResourceTypeId, ResourceId FROM @Resources -- TODO: Remove after deployment - ) A - GROUP BY ResourceTypeId, ResourceId - INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds - - WHILE EXISTS (SELECT * FROM @RTs) + IF EXISTS (SELECT * FROM @ResourcesLake) + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @ResourcesLake GROUP BY ResourceTypeId, ResourceId + ELSE + INSERT INTO @InputIds SELECT ResourceTypeId, ResourceId FROM @Resources GROUP BY ResourceTypeId, ResourceId + + INSERT INTO @ExistingIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), A.ResourceId + FROM @InputIds A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @InsertedIdsReference C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + WHERE C.ResourceIdInt IS NOT NULL OR B.ResourceIdInt IS NOT NULL + + DELETE FROM @InsertIds + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsResource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 BEGIN - SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - INSERT INTO @ExistingIds - ( ResourceTypeId, ResourceIdInt, ResourceId ) - SELECT @RT, ResourceIdInt, A.ResourceId - FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId - - DELETE FROM @InsertIds - - INSERT INTO @InsertIds - ( ResourceIndex, ResourceId ) - SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId - FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A - WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) - - SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - - INSERT INTO dbo.ResourceIdIntMap - ( ResourceTypeId, ResourceIdInt, ResourceId ) - OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId - FROM @InsertIds - END - - DELETE FROM @RTs WHERE ResourceTypeId = @RT + INSERT INTO @InsertedIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds END - INSERT INTO @ResourcesWithIds - ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) - SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile - FROM (SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId = CASE WHEN OffsetInFile IS NOT NULL THEN @TransactionId END, OffsetInFile FROM @ResourcesLake - UNION ALL - SELECT ResourceTypeId, ResourceId, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL FROM @Resources - ) A - LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId - --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Action='Insert',@Target='@ResourcesWithIds',@Rows=@@rowcount,@Start=@st - --- Prepare id map for resources End --------------------------------------------------------------------------- -END TRY -BEGIN CATCH - IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st - - IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' - BEGIN - DELETE FROM @ResourcesWithIds - DELETE FROM @ReferenceSearchParamsWithIds - DELETE FROM @InputIds - DELETE FROM @RTs - DELETE FROM @InsertedIds - DELETE FROM @ExistingIds - - GOTO RetryResourceIdIntMapInsert - END + IF EXISTS (SELECT * FROM @ResourcesLake) + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile + FROM @ResourcesLake A + LEFT OUTER JOIN @InsertedIdsResource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIdsResource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId ELSE - THROW -END CATCH - ---EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Text='ResourceIdIntMap populated' + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, HasVersionToCompare, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, KeepHistory, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL + FROM @Resources A + LEFT OUTER JOIN @InsertedIdsResource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIdsResource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + -- Prepare id map for resources End --------------------------------------------------------------------------- -BEGIN TRY DECLARE @Existing AS TABLE (ResourceTypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)) DECLARE @ResourceInfos AS TABLE @@ -301,7 +260,39 @@ BEGIN TRY DELETE FROM dbo.ResourceWriteClaim WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount - DELETE FROM dbo.ReferenceSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + DELETE FROM dbo.ResourceReferenceSearchParams + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) + SET @CurrentRows = @@rowcount + SET @AffectedRows += @CurrentRows + -- start deleting from ResourceIdIntMap + INSERT INTO @CurrentRefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @CurrentRefIdsRaw + SET @CurrentRows = @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove not reused + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM @ReferenceSearchParamsWithIds B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced in Resources + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove still referenced in ResourceReferenceSearchParams + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- delete from id map + DELETE FROM B FROM @CurrentRefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END + DELETE FROM dbo.StringReferenceSearchParams WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount DELETE FROM dbo.TokenSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount @@ -333,6 +324,16 @@ BEGIN TRY --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' END + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsResource + + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsReference + INSERT INTO dbo.Resource ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, FileId, OffsetInFile ) SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, @TransactionId, FileId, OffsetInFile @@ -591,17 +592,37 @@ BEGIN TRY IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st - IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') -- handles old and separated tables - THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; - ELSE - THROW + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation + OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @ResourcesWithIds + DELETE FROM @ReferenceSearchParamsWithIds + DELETE FROM @CurrentRefIdsRaw + DELETE FROM @CurrentRefIds + DELETE FROM @InputIds + DELETE FROM @InsertIds + DELETE FROM @InsertedIdsReference + DELETE FROM @ExistingIdsReference + DELETE FROM @InsertedIdsResource + DELETE FROM @ExistingIdsResource + DELETE FROM @Existing + DELETE FROM @ResourceInfos + DELETE FROM @PreviousSurrogateIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW END CATCH GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql index bf43c913be..159000e740 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql @@ -5,23 +5,64 @@ AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId) - ,@st datetime = getUTCdate() - ,@TypeId smallint + ,@st datetime + ,@Rows int + ,@DeletedIdMap int SET @AffectedRows = 0 -BEGIN TRY - DELETE FROM dbo.Resource WHERE HistoryTransactionId = @TransactionId AND RawResource = 0xF - SET @AffectedRows += @@rowcount - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@AffectedRows +Retry: +BEGIN TRY + DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + + BEGIN TRANSACTION - -- TODO: Move to a separate stored procedure? + SET @st = getUTCdate() + DELETE FROM A + OUTPUT deleted.ResourceTypeId, deleted.ResourceIdInt INTO @Ids + FROM dbo.Resource A + WHERE HistoryTransactionId = @TransactionId + SET @Rows = @@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@Rows + SET @AffectedRows += @Rows + + SET @st = getUTCdate() + IF @Rows > 0 + BEGIN + -- remove referenced in resources + DELETE FROM A FROM @Ids A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + -- remove referenced in reference search params + DELETE FROM A FROM @Ids A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + -- delete from id map + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap + + COMMIT TRANSACTION + + SET @st = getUTCdate() UPDATE dbo.Resource SET TransactionId = NULL WHERE TransactionId = @TransactionId EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Target='Resource',@Action='Update',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; - THROW + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error' + IF error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @Ids + GOTO Retry + END + ELSE + THROW END CATCH GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql index 5e43010cf4..03f392222e 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/UpdateResourceSearchParams.sql @@ -22,10 +22,66 @@ set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),'Input=Empty') - ,@Rows int + ,@ResourceRows int + ,@InsertRows int + ,@DeletedIdMap int + ,@FirstIdInt bigint + ,@CurrentRows int +RetryResourceIdIntMapLogic: BEGIN TRY DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceSurrogateId bigint NOT NULL) + DECLARE @CurrentRefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + DECLARE @CurrentRefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) + DECLARE @InputRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertRefIds AS TABLE (ResourceTypeId smallint NOT NULL, IdIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedRefIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ReferenceSearchParamsWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,ReferenceResourceVersion int NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) + ) + + -- Prepare insert into ResourceIdIntMap outside of transaction to minimize blocking + INSERT INTO @InputRefIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId FROM @ReferenceSearchParams WHERE ReferenceResourceTypeId IS NOT NULL + + INSERT INTO @ExistingRefIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputRefIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + + INSERT INTO @InsertRefIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputRefIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingRefIds B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @InsertRows = (SELECT count(*) FROM @InsertRefIds) + IF @InsertRows > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @InsertRows, @FirstIdInt OUT + + INSERT INTO @InsertedRefIds + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertRefIds + END + + INSERT INTO @ReferenceSearchParamsWithIds + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt, ReferenceResourceVersion ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), ReferenceResourceVersion + FROM @ReferenceSearchParams A + LEFT OUTER JOIN @InsertedRefIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingRefIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId BEGIN TRANSACTION @@ -44,39 +100,71 @@ BEGIN TRY FROM dbo.Resource B WHERE EXISTS (SELECT * FROM @Resources A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) AND B.IsHistory = 0 - SET @Rows = @@rowcount + SET @ResourceRows = @@rowcount -- First, delete all the search params of the resources to reindex. - DELETE FROM B FROM @Ids A JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM dbo.ResourceReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - DELETE FROM B FROM dbo.StringReferenceSearchParams B WHERE EXISTS (SELECT * FROM @Ids A WHERE A.ResourceTypeId = B.ResourceTypeId AND A.ResourceSurrogateId = B.ResourceSurrogateId) - DELETE FROM B FROM @Ids A JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - DELETE FROM B FROM @Ids A JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceWriteClaim B ON B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B + OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @CurrentRefIdsRaw + FROM @Ids A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.UriSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.NumberSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.QuantitySearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.DateTimeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId -- Next, insert all the new search params. INSERT INTO dbo.ResourceWriteClaim ( ResourceSurrogateId, ClaimTypeId, ClaimValue ) SELECT ResourceSurrogateId, ClaimTypeId, ClaimValue FROM @ResourceWriteClaims + + -- start delete logic from ResourceIdIntMap + INSERT INTO @CurrentRefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @CurrentRefIdsRaw + SET @CurrentRows = @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove not reused + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM @ReferenceSearchParamsWithIds B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced by resources + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- remove referenced by reference search params + DELETE FROM A FROM @CurrentRefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @CurrentRows -= @@rowcount + IF @CurrentRows > 0 + BEGIN + -- finally delete from id map + DELETE FROM B FROM @CurrentRefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END - -- TODO: Add insert into ResourceIdIntMap + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedRefIds INSERT INTO dbo.ResourceReferenceSearchParams - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) - SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, B.ResourceIdInt - FROM @ReferenceSearchParams A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM @ReferenceSearchParamsWithIds INSERT INTO dbo.StringReferenceSearchParams ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) @@ -151,13 +239,30 @@ BEGIN TRY COMMIT TRANSACTION - SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @Rows + SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @ResourceRows - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@ResourceRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; - THROW + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation + OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @Ids + DELETE FROM @InputRefIds + DELETE FROM @CurrentRefIdsRaw + DELETE FROM @CurrentRefIds + DELETE FROM @ExistingRefIds + DELETE FROM @InsertRefIds + DELETE FROM @InsertedRefIds + DELETE FROM @ReferenceSearchParamsWithIds + + GOTO RetryResourceIdIntMapLogic + END + ELSE + THROW END CATCH GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql index 9ce399c2f7..054f3c9c82 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Types/ResourceListLake.sql @@ -14,6 +14,7 @@ CREATE TYPE dbo.ResourceListLake AS TABLE ,IsRawResourceMetaSet bit NOT NULL ,RequestMethod varchar(10) NULL ,SearchParamHash varchar(64) NULL + ,FileId bigint NULL ,OffsetInFile int NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql index e0a5710bc8..70e94e58dc 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql @@ -19,15 +19,3 @@ SELECT ResourceTypeId ,IsResourceRef FROM dbo.StringReferenceSearchParams GO -CREATE TRIGGER dbo.ReferenceSearchParamDel ON dbo.ReferenceSearchParam INSTEAD OF DELETE -AS -BEGIN - DELETE FROM A - FROM dbo.ResourceReferenceSearchParams A - WHERE EXISTS (SELECT * FROM Deleted B WHERE B.IsResourceRef = 1 AND B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) - - DELETE FROM A - FROM dbo.StringReferenceSearchParams A - WHERE EXISTS (SELECT * FROM Deleted B WHERE B.IsResourceRef = 0 AND B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -END -GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index 73dd960b51..91e9fa42b1 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -145,6 +145,7 @@ private async Task PutRawResourcesIntoAdls(IReadOnlyList r var offset = 0; foreach (var resource in resources) { + resource.FileId = transactionId; resource.OffsetInFile = offset; var line = resource.ResourceWrapper.RawResource.Data; offset += Encoding.UTF8.GetByteCount(line) + eol; @@ -837,7 +838,7 @@ public async Task GetAsync(ResourceKey key, CancellationToken c public async Task HardDeleteAsync(ResourceKey key, bool keepCurrentVersion, bool allowPartialSuccess, CancellationToken cancellationToken) { - await _sqlStoreClient.HardDeleteAsync(_model.GetResourceTypeId(key.ResourceType), key.Id, keepCurrentVersion, _coreFeatures.SupportsResourceChangeCapture, cancellationToken); + await _sqlStoreClient.HardDeleteAsync(_model.GetResourceTypeId(key.ResourceType), key.Id, keepCurrentVersion, cancellationToken); } public async Task BulkUpdateSearchParameterIndicesAsync(IReadOnlyCollection resources, CancellationToken cancellationToken) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index e29449624b..731c9a98b8 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -41,13 +41,12 @@ public SqlStoreClient(ISqlRetryService sqlRetryService, ILogger _logger = EnsureArg.IsNotNull(logger, nameof(logger)); } - public async Task HardDeleteAsync(short resourceTypeId, string resourceId, bool keepCurrentVersion, bool isResourceChangeCaptureEnabled, CancellationToken cancellationToken) + public async Task HardDeleteAsync(short resourceTypeId, string resourceId, bool keepCurrentVersion, CancellationToken cancellationToken) { using var cmd = new SqlCommand() { CommandText = "dbo.HardDeleteResource", CommandType = CommandType.StoredProcedure }; cmd.Parameters.AddWithValue("@ResourceTypeId", resourceTypeId); cmd.Parameters.AddWithValue("@ResourceId", resourceId); cmd.Parameters.AddWithValue("@KeepCurrentVersion", keepCurrentVersion); - cmd.Parameters.AddWithValue("@IsResourceChangeCaptureEnabled", isResourceChangeCaptureEnabled); await cmd.ExecuteNonQueryAsync(_sqlRetryService, _logger, cancellationToken); } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs index 40615a2f6a..b364e05141 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/MergeResourceWrapper.cs @@ -31,6 +31,11 @@ internal MergeResourceWrapper(ResourceWrapper resourceWrapper, bool keepHistory, /// public bool HasVersionToCompare { get; internal set; } + /// + /// Adls file Id + /// + public long? FileId { get; internal set; } + /// /// Reasource record offset in adls file /// diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs index 25ad1241d5..3bb04cbb0d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/TvpRowGeneration/Merge/ResourceListLakeRowGenerator.cs @@ -34,7 +34,7 @@ public IEnumerable GenerateRows(IReadOnlyList Date: Wed, 11 Dec 2024 15:31:38 -0800 Subject: [PATCH 039/111] fix diff --- .../Features/Schema/Migrations/84.diff.sql | 1 - 1 file changed, 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index d9fd87e69a..117adf7987 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -2093,7 +2093,6 @@ SELECT A.ResourceTypeId ,IsResourceRef FROM dbo.ResourceReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt - WHERE HistoryTransactionId IS NULL UNION ALL SELECT ResourceTypeId ,ResourceSurrogateId From ad7576a9b6e24db34eeb045346eb69299400c617 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 11 Dec 2024 15:31:50 -0800 Subject: [PATCH 040/111] resourceids --- tools/PerfTester/Program.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/tools/PerfTester/Program.cs b/tools/PerfTester/Program.cs index 580e5c04e2..ae694e998b 100644 --- a/tools/PerfTester/Program.cs +++ b/tools/PerfTester/Program.cs @@ -543,7 +543,7 @@ private static void DumpResourceIds() var ret = cmd.ExecuteScalar(); if (ret == DBNull.Value) { - using var cmd2 = new SqlCommand("SELECT ResourceTypeId, ResourceId FROM dbo.Resource WHERE IsHistory = 0 ORDER BY ResourceTypeId, ResourceId OPTION (MAXDOP 1)", conn); + using var cmd2 = new SqlCommand("SELECT ResourceTypeId, ResourceId FROM dbo.Resource WHERE IsHistory = 0", conn); // no need to sort to simulate random access cmd2.CommandTimeout = 0; using var reader = cmd2.ExecuteReader(); while (reader.Read()) From 8867758c2e15ab7163b389a78d89730f53a33ea8 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 12 Dec 2024 11:11:39 -0800 Subject: [PATCH 041/111] filter out null ref resourec type --- .../Features/Schema/Migrations/84.diff.sql | 2 ++ .../Features/Schema/Migrations/84.sql | 3 ++- .../Features/Schema/Sql/Sprocs/MergeResources.sql | 1 + 3 files changed, 5 insertions(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 117adf7987..2527addb84 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -1004,6 +1004,7 @@ BEGIN TRY FROM @ReferenceSearchParams A LEFT OUTER JOIN @InsertedIdsReference B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId LEFT OUTER JOIN @ExistingIdsReference C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + WHERE ReferenceResourceTypeId IS NOT NULL -- Prepare id map for reference search params End --------------------------------------------------------------------------- -- Prepare id map for resources Start --------------------------------------------------------------------------- @@ -2770,6 +2771,7 @@ BEGIN TRY FROM @ReferenceSearchParams A LEFT OUTER JOIN @InsertedIdsReference B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId LEFT OUTER JOIN @ExistingIdsReference C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + WHERE ReferenceResourceTypeId IS NOT NULL -- Prepare id map for reference search params End --------------------------------------------------------------------------- -- Prepare id map for resources Start --------------------------------------------------------------------------- diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 5f51d22ccd..78ee0f67ab 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -3836,7 +3836,8 @@ BEGIN TRY LEFT OUTER JOIN @ExistingIdsReference AS C ON C.ResourceTypeId = A.ReferenceResourceTypeId - AND C.ResourceId = A.ReferenceResourceId; + AND C.ResourceId = A.ReferenceResourceId + WHERE ReferenceResourceTypeId IS NOT NULL; DELETE @InputIds; IF EXISTS (SELECT * FROM @ResourcesLake) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql index 0c670c5c80..166371b66d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResources.sql @@ -120,6 +120,7 @@ BEGIN TRY FROM @ReferenceSearchParams A LEFT OUTER JOIN @InsertedIdsReference B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId LEFT OUTER JOIN @ExistingIdsReference C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + WHERE ReferenceResourceTypeId IS NOT NULL -- Prepare id map for reference search params End --------------------------------------------------------------------------- -- Prepare id map for resources Start --------------------------------------------------------------------------- From e56f59933c825c9afc2014619f11e206d5eac7b8 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 12 Dec 2024 13:13:54 -0800 Subject: [PATCH 042/111] handle search params updates in parallel with data move --- .../Features/Schema/Migrations/84.diff.sql | 5 ++--- 1 file changed, 2 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 2527addb84..d9e132f453 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -613,7 +613,7 @@ INSERT INTO dbo.ResourceChangeData FROM (SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @Resources UNION ALL SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @ResourcesLake) A WHERE IsHistory = 0 GO --- The following 2 procs are special for data movement +-- The following 2 procs and trigger are special for data movement GO CREATE PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT @@ -1528,6 +1528,7 @@ BEGIN SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile FROM Inserted WHERE IsHistory = 0 + AND NOT EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- Avoid dups caused by search params update INSERT INTO dbo.HistoryResources ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) @@ -2649,8 +2650,6 @@ BEGIN CATCH THROW END CATCH GO ---DROP PROCEDURE dbo.MergeResources -GO ALTER PROCEDURE dbo.MergeResources -- This stored procedure can be used for: -- 1. Ordinary put with single version per resource in input From c59a7ceb2d6415986d0460fd00f36e935e28ae0f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 12 Dec 2024 15:03:11 -0800 Subject: [PATCH 043/111] Added id join in include queries --- .../Features/Schema/Migrations/84.diff.sql | 7 +++-- .../Features/Schema/Migrations/84.sql | 5 +++- .../Sql/Tables/ReferenceSearchParam.sql | 3 ++- .../Schema/Sql/Views/ReferenceSearchParam.sql | 2 ++ .../QueryGenerators/SqlQueryGenerator.cs | 26 +++++++++++++++---- 5 files changed, 34 insertions(+), 9 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index d9e132f453..f4b42e08b8 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -535,14 +535,13 @@ BEGIN WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) EXECUTE(' -CREATE VIEW dbo.ReferenceSearchParam -AS SELECT A.ResourceTypeId ,ResourceSurrogateId ,SearchParamId ,BaseUri ,ReferenceResourceTypeId ,ReferenceResourceId = B.ResourceId + ,ReferenceResourceIdInt ,IsResourceRef FROM dbo.ResourceReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt @@ -553,6 +552,7 @@ SELECT ResourceTypeId ,BaseUri ,NULL ,ReferenceResourceId + ,NULL ,IsResourceRef FROM dbo.StringReferenceSearchParams UNION ALL @@ -563,6 +563,7 @@ SELECT ResourceTypeId ,ReferenceResourceTypeId ,ReferenceResourceId ,NULL + ,NULL FROM dbo.ReferenceSearchParamTbl ') @@ -2092,6 +2093,7 @@ SELECT A.ResourceTypeId ,BaseUri ,ReferenceResourceTypeId ,ReferenceResourceId = B.ResourceId + ,ReferenceResourceIdInt ,IsResourceRef FROM dbo.ResourceReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt @@ -2102,6 +2104,7 @@ SELECT ResourceTypeId ,BaseUri ,NULL ,ReferenceResourceId + ,NULL ,IsResourceRef FROM dbo.StringReferenceSearchParams GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 78ee0f67ab..98233f73c7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -669,8 +669,9 @@ CREATE TABLE dbo.ReferenceSearchParam ( SearchParamId SMALLINT NOT NULL, BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceId VARCHAR (768) COLLATE Latin1_General_100_CS_AS NOT NULL, ReferenceResourceIdInt BIGINT NOT NULL, - ReferenceResourceId VARCHAR (768) COLLATE Latin1_General_100_CS_AS NOT NULL + IsResourceRef BIT NOT NULL ); @@ -6058,6 +6059,7 @@ SELECT A.ResourceTypeId, BaseUri, ReferenceResourceTypeId, B.ResourceId AS ReferenceResourceId, + ReferenceResourceIdInt, IsResourceRef FROM dbo.ResourceReferenceSearchParams AS A LEFT OUTER JOIN @@ -6071,6 +6073,7 @@ SELECT ResourceTypeId, BaseUri, NULL, ReferenceResourceId, + NULL, IsResourceRef FROM dbo.StringReferenceSearchParams; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql index 81beff5e88..d30f9dac97 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/ReferenceSearchParam.sql @@ -6,8 +6,9 @@ CREATE TABLE dbo.ReferenceSearchParam ,SearchParamId smallint NOT NULL ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL ,ReferenceResourceTypeId smallint NULL - ,ReferenceResourceIdInt bigint NOT NULL ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,IsResourceRef bit NOT NULL ) GO DROP TABLE dbo.ReferenceSearchParam diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql index 70e94e58dc..991a83b070 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/ReferenceSearchParam.sql @@ -6,6 +6,7 @@ SELECT A.ResourceTypeId ,BaseUri ,ReferenceResourceTypeId ,ReferenceResourceId = B.ResourceId + ,ReferenceResourceIdInt ,IsResourceRef FROM dbo.ResourceReferenceSearchParams A LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceIdInt = A.ReferenceResourceIdInt @@ -16,6 +17,7 @@ SELECT ResourceTypeId ,BaseUri ,NULL ,ReferenceResourceId + ,NULL ,IsResourceRef FROM dbo.StringReferenceSearchParams GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 189b5796d1..4f1b6ccef2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -294,7 +294,7 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions return null; } - // TODO: Remove when code starts using TokenSearchParamHighCard table + // TODO: Remove. This is not needed as we use precise statistics. private void AddOptionClause() { // if we have a complex query more than one SearchParemter, one of the parameters is "identifier", and we have an include @@ -687,8 +687,16 @@ private void HandleTableKindChain( .Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") .Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) - .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) - .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); + .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias); + if (_schemaInfo.Current >= SchemaVersionConstants.Lake) + { + StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceIdInt, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.CurrentResources.ResourceIdInt, referenceTargetResourceTableAlias) + .Append(" AND ").Append(VLatest.ReferenceSearchParam.IsResourceRef, referenceSourceTableAlias).AppendLine(" = 1"); + } + else + { + StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); + } // For reverse chaining, if there is a parameter on the _id search parameter, we need another join to get the resource ID of the reference source (all we have is the surrogate ID at this point) bool expressionOnTargetHandledBySecondJoin = chainedExpression.ExpressionOnTarget != null && chainedExpression.Reversed && chainedExpression.ExpressionOnTarget.AcceptVisitor(ExpressionContainsParameterVisitor.Instance, SearchParameterNames.Id); @@ -784,8 +792,16 @@ private void HandleTableKindInclude( StringBuilder.Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) - .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) - .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); + .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias); + if (_schemaInfo.Current >= SchemaVersionConstants.Lake) + { + StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceIdInt, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.CurrentResources.ResourceIdInt, referenceTargetResourceTableAlias) + .Append(" AND ").Append(VLatest.ReferenceSearchParam.IsResourceRef, referenceSourceTableAlias).AppendLine(" = 1"); + } + else + { + StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); + } using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { From 83c812ad0d317d83416890a1f4210542a6fc710d Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 12 Dec 2024 22:07:27 -0800 Subject: [PATCH 044/111] 84 diff fix --- .../Features/Schema/Migrations/84.diff.sql | 2 ++ 1 file changed, 2 insertions(+) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index f4b42e08b8..4252b5bc07 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -535,6 +535,8 @@ BEGIN WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) EXECUTE(' +CREATE VIEW dbo.ReferenceSearchParam +AS SELECT A.ResourceTypeId ,ResourceSurrogateId ,SearchParamId From 3019c0fe971866d1724e9c66fff0a9f82584c539 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sat, 14 Dec 2024 14:46:24 -0800 Subject: [PATCH 045/111] no CR on IsResourceRef --- .../Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 4f1b6ccef2..d6163191aa 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -690,7 +690,7 @@ private void HandleTableKindChain( .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias); if (_schemaInfo.Current >= SchemaVersionConstants.Lake) { - StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceIdInt, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.CurrentResources.ResourceIdInt, referenceTargetResourceTableAlias) + StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceIdInt, referenceSourceTableAlias).Append(" = ").Append(VLatest.CurrentResources.ResourceIdInt, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.IsResourceRef, referenceSourceTableAlias).AppendLine(" = 1"); } else @@ -795,7 +795,7 @@ private void HandleTableKindInclude( .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias); if (_schemaInfo.Current >= SchemaVersionConstants.Lake) { - StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceIdInt, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.CurrentResources.ResourceIdInt, referenceTargetResourceTableAlias) + StringBuilder.Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceIdInt, referenceSourceTableAlias).Append(" = ").Append(VLatest.CurrentResources.ResourceIdInt, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.IsResourceRef, referenceSourceTableAlias).AppendLine(" = 1"); } else From 46892b119d07934a968dc001af60eb2b39dff2a7 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sat, 14 Dec 2024 14:52:28 -0800 Subject: [PATCH 046/111] Removed not needed alias --- .../Features/Schema/Migrations/84.diff.sql | 4 ++-- .../Features/Schema/Migrations/84.sql | 4 ++-- .../Features/Schema/Sql/Views/Resource.sql | 4 ++-- 3 files changed, 6 insertions(+), 6 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 4252b5bc07..7d08a259e4 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -2120,7 +2120,7 @@ SELECT A.ResourceTypeId ,IsHistory ,IsDeleted ,RequestMethod - ,B.RawResource + ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId @@ -2139,7 +2139,7 @@ SELECT A.ResourceTypeId ,IsHistory ,IsDeleted ,RequestMethod - ,B.RawResource + ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 98233f73c7..0dbc3c4810 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -6088,7 +6088,7 @@ SELECT A.ResourceTypeId, IsHistory, IsDeleted, RequestMethod, - B.RawResource, + RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, @@ -6113,7 +6113,7 @@ SELECT A.ResourceTypeId, IsHistory, IsDeleted, RequestMethod, - B.RawResource, + RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql index cd23c932d3..fd65f70e3c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/Resource.sql @@ -8,7 +8,7 @@ SELECT A.ResourceTypeId ,IsHistory ,IsDeleted ,RequestMethod - ,B.RawResource + ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId @@ -27,7 +27,7 @@ SELECT A.ResourceTypeId ,IsHistory ,IsDeleted ,RequestMethod - ,B.RawResource + ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId From 4d65b4d51b11e47a8f0950abc6ce3feb475868e0 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 15 Dec 2024 10:06:41 -0800 Subject: [PATCH 047/111] no alias --- .../Features/Schema/Migrations/84.diff.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 7d08a259e4..fb31f4546a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -153,7 +153,7 @@ SELECT A.ResourceTypeId ,IsHistory ,IsDeleted ,RequestMethod - ,B.RawResource + ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId @@ -172,7 +172,7 @@ SELECT A.ResourceTypeId ,IsHistory ,IsDeleted ,RequestMethod - ,B.RawResource + ,RawResource ,IsRawResourceMetaSet ,SearchParamHash ,TransactionId From 73d02bea8487c512a66e938b3b02831dc2c9d233 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 16 Dec 2024 11:17:58 -0800 Subject: [PATCH 048/111] fixed RespurceIns trigger --- .../Features/Schema/Migrations/84.diff.sql | 46 +++++++++---------- 1 file changed, 22 insertions(+), 24 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index fb31f4546a..39e0f7f7e2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -1516,30 +1516,6 @@ BEGIN CATCH THROW END CATCH GO -CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT -AS -BEGIN - INSERT INTO dbo.RawResources - ( ResourceTypeId, ResourceSurrogateId, RawResource ) - SELECT ResourceTypeId, ResourceSurrogateId, RawResource - FROM Inserted A - WHERE RawResource IS NOT NULL - AND NOT EXISTS (SELECT * FROM dbo.RawResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- Avoid dups caused by hard deletes - - INSERT INTO dbo.CurrentResources - ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile - FROM Inserted - WHERE IsHistory = 0 - AND NOT EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -- Avoid dups caused by search params update - - INSERT INTO dbo.HistoryResources - ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) - SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile - FROM Inserted - WHERE IsHistory = 1 -END -GO COMMIT TRANSACTION GO ALTER PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId bigint, @AffectedRows int = NULL OUT @@ -2150,6 +2126,28 @@ SELECT A.ResourceTypeId LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt GO +ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT +AS +BEGIN + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + + INSERT INTO dbo.CurrentResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 0 + + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 1 +END +GO ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY AS -- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated From 4bbb3930b34bea8b184cfd8d5184252492ed7a9c Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 16 Dec 2024 16:15:08 -0800 Subject: [PATCH 049/111] Add ResourceTbl history update into temporary ResourceUpd trigger. --- .../Features/Schema/Migrations/84.diff.sql | 87 +++++++++++++++++++ 1 file changed, 87 insertions(+) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 39e0f7f7e2..e43d745d9b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -458,6 +458,11 @@ BEGIN IF NOT UPDATE(IsHistory) RAISERROR('Generic updates are not supported via Resource view',18,127) + UPDATE A + SET IsHistory = 1 + FROM dbo.ResourceTbl A + WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) + DELETE FROM A FROM dbo.CurrentResources A WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) @@ -2148,6 +2153,88 @@ BEGIN WHERE IsHistory = 1 END GO +ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE +AS +BEGIN + IF UPDATE(IsDeleted) AND UPDATE(RawResource) AND UPDATE(SearchParamHash) AND UPDATE(HistoryTransactionId) AND NOT UPDATE(IsHistory) -- hard delete resource + BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted A + JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + IF @@rowcount = 0 + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + + UPDATE B + SET IsDeleted = A.IsDeleted + ,SearchParamHash = A.SearchParamHash + ,HistoryTransactionId = A.HistoryTransactionId + FROM Inserted A + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + RETURN + END + + IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) -- reindex + BEGIN + UPDATE B + SET SearchParamHash = A.SearchParamHash + FROM Inserted A + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE A.IsHistory = 0 + + RETURN + END + + IF UPDATE(TransactionId) AND NOT UPDATE(IsHistory) -- cleanup trans + BEGIN + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted A + JOIN dbo.CurrentResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0 + + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted A + JOIN dbo.HistoryResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1 + + RETURN + END + + IF UPDATE(RawResource) -- invisible records + BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted A + JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + + IF @@rowcount = 0 + INSERT INTO dbo.RawResources + ( ResourceTypeId, ResourceSurrogateId, RawResource ) + SELECT ResourceTypeId, ResourceSurrogateId, RawResource + FROM Inserted + WHERE RawResource IS NOT NULL + END + + IF NOT UPDATE(IsHistory) + RAISERROR('Generic updates are not supported via Resource view',18,127) + + DELETE FROM A + FROM dbo.CurrentResources A + WHERE EXISTS (SELECT * FROM Inserted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) + + INSERT INTO dbo.HistoryResources + ( ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile ) + SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile + FROM Inserted + WHERE IsHistory = 1 +END +GO ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY AS -- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated From a79c4c3f6e8c08cfe068360b763b8d64e28e9a29 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 12:43:31 -0800 Subject: [PATCH 050/111] Final hard delete logic --- .../Features/Schema/Migrations/84.diff.sql | 296 ++++++++++++------ .../Features/Schema/Migrations/84.sql | 153 ++++++--- .../Schema/Sql/Sprocs/HardDeleteResource.sql | 130 +++++--- .../Storage/SqlServerFhirDataStore.cs | 3 +- .../Features/Storage/SqlStoreClient.cs | 3 +- tools/PerfTester/App.config | 2 +- tools/PerfTester/Program.cs | 10 +- 7 files changed, 392 insertions(+), 205 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index e43d745d9b..148810f8e6 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -477,6 +477,10 @@ GO CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE AS BEGIN + DELETE FROM A + FROM dbo.ResourceTbl A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) + DELETE FROM A FROM dbo.CurrentResources A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) @@ -1679,85 +1683,121 @@ ALTER PROCEDURE dbo.HardDeleteResource @ResourceTypeId smallint ,@ResourceId varchar(64) ,@KeepCurrentVersion bit - ,@IsResourceChangeCaptureEnabled bit = 1 -- TODO: Remove input parameter after deployment + ,@IsResourceChangeCaptureEnabled bit = 0 -- TODO: Remove input parameter after deployment + ,@MakeResourceInvisible bit = 0 AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = ' RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) + ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) ,@st datetime = getUTCdate() ,@TransactionId bigint - ,@DeletedIdMap int + ,@DeletedIdMap int = 0 ,@Rows int -BEGIN TRY +IF @IsResourceChangeCaptureEnabled = 1 + SET @MakeResourceInvisible = 1 + +SET @Mode += ' I='+convert(varchar,@MakeResourceInvisible) + +IF @MakeResourceInvisible = 1 +BEGIN EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT - SET @Mode = 'T='+convert(varchar,@TransactionId) + @Mode + SET @Mode += ' T='+convert(varchar,@TransactionId) +END - RetryResourceIdIntMapLogic: +DECLARE @Ids TABLE (ResourceSurrogateId bigint NOT NULL, ResourceIdInt bigint NOT NULL) +DECLARE @IdsDistinct TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) +DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) - IF @KeepCurrentVersion = 0 - BEGIN TRANSACTION - - DECLARE @SurrogateIds TABLE (ResourceSurrogateId bigint NOT NULL) - - UPDATE dbo.Resource - SET IsDeleted = 1 - ,RawResource = 0xF -- invisible value - ,SearchParamHash = NULL - ,HistoryTransactionId = @TransactionId - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 OR IsHistory = 1) +RetryResourceIdIntMapLogic: +BEGIN TRY + BEGIN TRANSACTION + + IF @MakeResourceInvisible = 1 + UPDATE dbo.Resource + SET IsDeleted = 1 + ,RawResource = 0xF -- invisible value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + ELSE + BEGIN + DELETE dbo.Resource + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) + AND RawResource <> 0xF + + INSERT INTO @IdsDistinct SELECT DISTINCT @ResourceTypeId, ResourceIdInt FROM @Ids WHERE ResourceIdInt IS NOT NULL + SET @Rows = @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM B FROM @IdsDistinct A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END IF @KeepCurrentVersion = 0 BEGIN - DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) - DECLARE @RefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) - -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceSearchParamTbl B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceSearchParamTbl B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw - FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - INSERT INTO @RefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw + FROM @Ids A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM @IdsDistinct -- is used above + INSERT INTO @IdsDistinct SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw SET @Rows = @@rowcount IF @Rows > 0 BEGIN - DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) SET @Rows -= @@rowcount IF @Rows > 0 BEGIN - DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) SET @Rows -= @@rowcount IF @Rows > 0 BEGIN - DELETE FROM B FROM @RefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt - SET @DeletedIdMap = @@rowcount + DELETE FROM B FROM @IdsDistinct A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap += @@rowcount END END END - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) END - IF @@trancount > 0 COMMIT TRANSACTION + COMMIT TRANSACTION - EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + IF @MakeResourceInvisible = 1 + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap END TRY @@ -1765,16 +1805,15 @@ BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st - IF error_number() = 547 -- reference violation + IF error_number() = 547 AND error_message() LIKE '%DELETE%'-- reference violation on DELETE BEGIN - DELETE FROM @SurrogateIds + DELETE FROM @Ids DELETE FROM @RefIdsRaw - DELETE FROM @RefIds - + DELETE FROM @IdsDistinct GOTO RetryResourceIdIntMapLogic END - ; - THROW + ELSE + THROW END CATCH GO -- Move data @@ -2235,6 +2274,22 @@ BEGIN WHERE IsHistory = 1 END GO +ALTER TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE +AS +BEGIN + DELETE FROM A + FROM dbo.CurrentResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) + + DELETE FROM A + FROM dbo.HistoryResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) + + DELETE FROM A + FROM dbo.RawResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END +GO ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY AS -- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated @@ -2643,84 +2698,120 @@ ALTER PROCEDURE dbo.HardDeleteResource @ResourceTypeId smallint ,@ResourceId varchar(64) ,@KeepCurrentVersion bit - ,@IsResourceChangeCaptureEnabled bit = 1 -- TODO: Remove input parameter after deployment + ,@IsResourceChangeCaptureEnabled bit = 0 -- TODO: Remove input parameter after deployment + ,@MakeResourceInvisible bit = 0 AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = ' RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) + ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) ,@st datetime = getUTCdate() ,@TransactionId bigint - ,@DeletedIdMap int + ,@DeletedIdMap int = 0 ,@Rows int -BEGIN TRY +IF @IsResourceChangeCaptureEnabled = 1 + SET @MakeResourceInvisible = 1 + +SET @Mode += ' I='+convert(varchar,@MakeResourceInvisible) + +IF @MakeResourceInvisible = 1 +BEGIN EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT - SET @Mode = 'T='+convert(varchar,@TransactionId) + @Mode + SET @Mode += ' T='+convert(varchar,@TransactionId) +END - RetryResourceIdIntMapLogic: +DECLARE @Ids TABLE (ResourceSurrogateId bigint NOT NULL, ResourceIdInt bigint NOT NULL) +DECLARE @IdsDistinct TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) +DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) - IF @KeepCurrentVersion = 0 - BEGIN TRANSACTION - - DECLARE @SurrogateIds TABLE (ResourceSurrogateId bigint NOT NULL) - - UPDATE dbo.Resource - SET IsDeleted = 1 - ,RawResource = 0xF -- invisible value - ,SearchParamHash = NULL - ,HistoryTransactionId = @TransactionId - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 OR IsHistory = 1) +RetryResourceIdIntMapLogic: +BEGIN TRY + BEGIN TRANSACTION + + IF @MakeResourceInvisible = 1 + UPDATE dbo.Resource + SET IsDeleted = 1 + ,RawResource = 0xF -- invisible value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + ELSE + BEGIN + DELETE dbo.Resource + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) + AND RawResource <> 0xF + + INSERT INTO @IdsDistinct SELECT DISTINCT @ResourceTypeId, ResourceIdInt FROM @Ids + SET @Rows = @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM B FROM @IdsDistinct A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END IF @KeepCurrentVersion = 0 BEGIN - DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) - DECLARE @RefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) - -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw - FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - INSERT INTO @RefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw + FROM @Ids A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM @IdsDistinct -- is used above + INSERT INTO @IdsDistinct SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw SET @Rows = @@rowcount IF @Rows > 0 BEGIN - DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) SET @Rows -= @@rowcount IF @Rows > 0 BEGIN - DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) SET @Rows -= @@rowcount IF @Rows > 0 BEGIN - DELETE FROM B FROM @RefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt - SET @DeletedIdMap = @@rowcount + DELETE FROM B FROM @IdsDistinct A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap += @@rowcount END END END - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) END - IF @@trancount > 0 COMMIT TRANSACTION + COMMIT TRANSACTION - EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + IF @MakeResourceInvisible = 1 + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap END TRY @@ -2728,12 +2819,11 @@ BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st - IF error_number() = 547 -- reference violation + IF error_number() = 547 AND error_message() LIKE '%DELETE%'-- reference violation on DELETE BEGIN - DELETE FROM @SurrogateIds + DELETE FROM @Ids DELETE FROM @RefIdsRaw - DELETE FROM @RefIds - + DELETE FROM @IdsDistinct GOTO RetryResourceIdIntMapLogic END ELSE diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index 0dbc3c4810..a11ab332d5 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -3440,51 +3440,104 @@ END CATCH GO CREATE PROCEDURE dbo.HardDeleteResource -@ResourceTypeId SMALLINT, @ResourceId VARCHAR (64), @KeepCurrentVersion BIT, @IsResourceChangeCaptureEnabled BIT=1 +@ResourceTypeId SMALLINT, @ResourceId VARCHAR (64), @KeepCurrentVersion BIT, @IsResourceChangeCaptureEnabled BIT=0, @MakeResourceInvisible BIT=0 AS SET NOCOUNT ON; -DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = ' RT=' + CONVERT (VARCHAR, @ResourceTypeId) + ' R=' + @ResourceId + ' V=' + CONVERT (VARCHAR, @KeepCurrentVersion), @st AS DATETIME = getUTCdate(), @TransactionId AS BIGINT, @DeletedIdMap AS INT, @Rows AS INT; -EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUTPUT; -SET @Mode = 'T=' + CONVERT (VARCHAR, @TransactionId) + @Mode; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'RT=' + CONVERT (VARCHAR, @ResourceTypeId) + ' R=' + @ResourceId + ' V=' + CONVERT (VARCHAR, @KeepCurrentVersion), @st AS DATETIME = getUTCdate(), @TransactionId AS BIGINT, @DeletedIdMap AS INT = 0, @Rows AS INT; +IF @IsResourceChangeCaptureEnabled = 1 + SET @MakeResourceInvisible = 1; +SET @Mode += ' I=' + CONVERT (VARCHAR, @MakeResourceInvisible); +IF @MakeResourceInvisible = 1 + BEGIN + EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUTPUT; + SET @Mode += ' T=' + CONVERT (VARCHAR, @TransactionId); + END +DECLARE @Ids TABLE ( + ResourceSurrogateId BIGINT NOT NULL, + ResourceIdInt BIGINT NOT NULL); +DECLARE @IdsDistinct TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)); +DECLARE @RefIdsRaw TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceIdInt BIGINT NOT NULL); RetryResourceIdIntMapLogic: BEGIN TRY - IF @KeepCurrentVersion = 0 - BEGIN TRANSACTION; - DECLARE @SurrogateIds TABLE ( - ResourceSurrogateId BIGINT NOT NULL); - UPDATE dbo.Resource - SET IsDeleted = 1, - RawResource = 0xF, - SearchParamHash = NULL, - HistoryTransactionId = @TransactionId - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 - OR IsHistory = 1); + BEGIN TRANSACTION; + IF @MakeResourceInvisible = 1 + UPDATE dbo.Resource + SET IsDeleted = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1); + ELSE + BEGIN + DELETE dbo.Resource + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1) + AND RawResource <> 0xF; + INSERT INTO @IdsDistinct + SELECT DISTINCT @ResourceTypeId, + ResourceIdInt + FROM @Ids; + SET @Rows = @@rowcount; + IF @Rows > 0 + BEGIN + DELETE A + FROM @IdsDistinct AS A + WHERE EXISTS (SELECT * + FROM dbo.CurrentResources AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt); + SET @Rows -= @@rowcount; + IF @Rows > 0 + BEGIN + DELETE A + FROM @IdsDistinct AS A + WHERE EXISTS (SELECT * + FROM dbo.ResourceReferenceSearchParams AS B + WHERE B.ReferenceResourceTypeId = A.ResourceTypeId + AND B.ReferenceResourceIdInt = A.ResourceIdInt); + SET @Rows -= @@rowcount; + IF @Rows > 0 + BEGIN + DELETE B + FROM @IdsDistinct AS A + INNER LOOP JOIN + dbo.ResourceIdIntMap AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceIdInt = A.ResourceIdInt; + SET @DeletedIdMap = @@rowcount; + END + END + END + END IF @KeepCurrentVersion = 0 BEGIN - DECLARE @RefIdsRaw TABLE ( - ResourceTypeId SMALLINT NOT NULL, - ResourceIdInt BIGINT NOT NULL); - DECLARE @RefIds TABLE ( - ResourceTypeId SMALLINT NOT NULL, - ResourceIdInt BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.ResourceWriteClaim AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.ResourceReferenceSearchParams AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); - INSERT INTO @RefIds + DELETE @IdsDistinct; + INSERT INTO @IdsDistinct SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw; @@ -3492,7 +3545,7 @@ BEGIN TRY IF @Rows > 0 BEGIN DELETE A - FROM @RefIds AS A + FROM @IdsDistinct AS A WHERE EXISTS (SELECT * FROM dbo.CurrentResources AS B WHERE B.ResourceTypeId = A.ResourceTypeId @@ -3501,7 +3554,7 @@ BEGIN TRY IF @Rows > 0 BEGIN DELETE A - FROM @RefIds AS A + FROM @IdsDistinct AS A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams AS B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId @@ -3510,116 +3563,116 @@ BEGIN TRY IF @Rows > 0 BEGIN DELETE B - FROM @RefIds AS A + FROM @IdsDistinct AS A INNER LOOP JOIN dbo.ResourceIdIntMap AS B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt; - SET @DeletedIdMap = @@rowcount; + SET @DeletedIdMap += @@rowcount; END END END DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.StringReferenceSearchParams AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.TokenSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.TokenText AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.StringSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.UriSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.NumberSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.QuantitySearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.DateTimeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B - FROM @SurrogateIds AS A + FROM @Ids AS A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); END - IF @@trancount > 0 - COMMIT TRANSACTION; - EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + COMMIT TRANSACTION; + IF @MakeResourceInvisible = 1 + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = @DeletedIdMap; END TRY BEGIN CATCH @@ -3629,9 +3682,9 @@ BEGIN CATCH IF error_number() = 547 AND error_message() LIKE '%DELETE%' BEGIN - DELETE @SurrogateIds; + DELETE @Ids; DELETE @RefIdsRaw; - DELETE @RefIds; + DELETE @IdsDistinct; GOTO RetryResourceIdIntMapLogic; END ELSE diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql index 3ae86f6ad5..eb057d70df 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql @@ -2,83 +2,120 @@ @ResourceTypeId smallint ,@ResourceId varchar(64) ,@KeepCurrentVersion bit - ,@IsResourceChangeCaptureEnabled bit = 1 -- TODO: Remove input parameter after deployment + ,@IsResourceChangeCaptureEnabled bit = 0 -- TODO: Remove input parameter after deployment + ,@MakeResourceInvisible bit = 0 AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = ' RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) + ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) ,@st datetime = getUTCdate() ,@TransactionId bigint - ,@DeletedIdMap int + ,@DeletedIdMap int = 0 ,@Rows int -EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT -SET @Mode = 'T='+convert(varchar,@TransactionId) + @Mode +IF @IsResourceChangeCaptureEnabled = 1 + SET @MakeResourceInvisible = 1 + +SET @Mode += ' I='+convert(varchar,@MakeResourceInvisible) + +IF @MakeResourceInvisible = 1 +BEGIN + EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT + SET @Mode += ' T='+convert(varchar,@TransactionId) +END + +DECLARE @Ids TABLE (ResourceSurrogateId bigint NOT NULL, ResourceIdInt bigint NOT NULL) +DECLARE @IdsDistinct TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) +DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) RetryResourceIdIntMapLogic: BEGIN TRY - IF @KeepCurrentVersion = 0 - BEGIN TRANSACTION + BEGIN TRANSACTION - DECLARE @SurrogateIds TABLE (ResourceSurrogateId bigint NOT NULL) - - UPDATE dbo.Resource - SET IsDeleted = 1 - ,RawResource = 0xF -- invisible value - ,SearchParamHash = NULL - ,HistoryTransactionId = @TransactionId - OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId = @ResourceId - AND (@KeepCurrentVersion = 0 OR IsHistory = 1) + IF @MakeResourceInvisible = 1 + UPDATE dbo.Resource + SET IsDeleted = 1 + ,RawResource = 0xF -- invisible value + ,SearchParamHash = NULL + ,HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + ELSE + BEGIN + DELETE dbo.Resource + OUTPUT deleted.ResourceSurrogateId, deleted.ResourceIdInt INTO @Ids + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 OR IsHistory = 1) + AND RawResource <> 0xF + + INSERT INTO @IdsDistinct SELECT DISTINCT @ResourceTypeId, ResourceIdInt FROM @Ids + SET @Rows = @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + DELETE FROM B FROM @IdsDistinct A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + END + END IF @KeepCurrentVersion = 0 BEGIN - DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) - DECLARE @RefIds TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) - -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw - FROM @SurrogateIds A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - INSERT INTO @RefIds SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw + FROM @Ids A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM @IdsDistinct -- is used above + INSERT INTO @IdsDistinct SELECT DISTINCT ResourceTypeId, ResourceIdInt FROM @RefIdsRaw SET @Rows = @@rowcount IF @Rows > 0 BEGIN - DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) SET @Rows -= @@rowcount IF @Rows > 0 BEGIN - DELETE FROM A FROM @RefIds A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + DELETE FROM A FROM @IdsDistinct A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) SET @Rows -= @@rowcount IF @Rows > 0 BEGIN - DELETE FROM B FROM @RefIds A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt - SET @DeletedIdMap = @@rowcount + DELETE FROM B FROM @IdsDistinct A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap += @@rowcount END END END - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @SurrogateIds A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.UriSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.NumberSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.QuantitySearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.DateTimeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenTokenCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenDateTimeCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenQuantityCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenStringCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenNumberNumberCompositeSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) END - IF @@trancount > 0 COMMIT TRANSACTION + COMMIT TRANSACTION - EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId + IF @MakeResourceInvisible = 1 + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap END TRY @@ -88,10 +125,9 @@ BEGIN CATCH IF error_number() = 547 AND error_message() LIKE '%DELETE%'-- reference violation on DELETE BEGIN - DELETE FROM @SurrogateIds + DELETE FROM @Ids DELETE FROM @RefIdsRaw - DELETE FROM @RefIds - + DELETE FROM @IdsDistinct GOTO RetryResourceIdIntMapLogic END ELSE diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index 91e9fa42b1..af52edca31 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -838,7 +838,8 @@ public async Task GetAsync(ResourceKey key, CancellationToken c public async Task HardDeleteAsync(ResourceKey key, bool keepCurrentVersion, bool allowPartialSuccess, CancellationToken cancellationToken) { - await _sqlStoreClient.HardDeleteAsync(_model.GetResourceTypeId(key.ResourceType), key.Id, keepCurrentVersion, cancellationToken); + var makeResourceInvisible = _coreFeatures.SupportsResourceChangeCapture; // TODO: For case when Raw in Lake are supported, this should be true. + await _sqlStoreClient.HardDeleteAsync(_model.GetResourceTypeId(key.ResourceType), key.Id, keepCurrentVersion, makeResourceInvisible, cancellationToken); } public async Task BulkUpdateSearchParameterIndicesAsync(IReadOnlyCollection resources, CancellationToken cancellationToken) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 731c9a98b8..776a1aac80 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -41,12 +41,13 @@ public SqlStoreClient(ISqlRetryService sqlRetryService, ILogger _logger = EnsureArg.IsNotNull(logger, nameof(logger)); } - public async Task HardDeleteAsync(short resourceTypeId, string resourceId, bool keepCurrentVersion, CancellationToken cancellationToken) + public async Task HardDeleteAsync(short resourceTypeId, string resourceId, bool keepCurrentVersion, bool makeResourceInvisible, CancellationToken cancellationToken) { using var cmd = new SqlCommand() { CommandText = "dbo.HardDeleteResource", CommandType = CommandType.StoredProcedure }; cmd.Parameters.AddWithValue("@ResourceTypeId", resourceTypeId); cmd.Parameters.AddWithValue("@ResourceId", resourceId); cmd.Parameters.AddWithValue("@KeepCurrentVersion", keepCurrentVersion); + cmd.Parameters.AddWithValue("@MakeResourceInvisible", makeResourceInvisible); await cmd.ExecuteNonQueryAsync(_sqlRetryService, _logger, cancellationToken); } diff --git a/tools/PerfTester/App.config b/tools/PerfTester/App.config index 0a24f67e93..ff7e939433 100644 --- a/tools/PerfTester/App.config +++ b/tools/PerfTester/App.config @@ -22,7 +22,7 @@ - + diff --git a/tools/PerfTester/Program.cs b/tools/PerfTester/Program.cs index ae694e998b..79116e0829 100644 --- a/tools/PerfTester/Program.cs +++ b/tools/PerfTester/Program.cs @@ -337,11 +337,17 @@ private static void ExecuteParallelCalls(ReadOnlyList<(short ResourceTypeId, str Interlocked.Increment(ref errors); } } - else if (_callType == "HardDelete") + else if (_callType == "HardDeleteNoInvisible") { var typeId = resourceIds.Item2.First().ResourceTypeId; var id = resourceIds.Item2.First().ResourceId; - _store.HardDeleteAsync(typeId, id, false, CancellationToken.None).Wait(); + _store.HardDeleteAsync(typeId, id, false, false, CancellationToken.None).Wait(); + } + else if (_callType == "HardDeleteWithInvisible") + { + var typeId = resourceIds.Item2.First().ResourceTypeId; + var id = resourceIds.Item2.First().ResourceId; + _store.HardDeleteAsync(typeId, id, false, true, CancellationToken.None).Wait(); } else { From 730260beef42fddc63116831c7cb47a69439ec4f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 13:33:08 -0800 Subject: [PATCH 051/111] final delete invisible history --- .../Features/Schema/Migrations/84.diff.sql | 94 +++++++++++++++++-- .../Features/Schema/Migrations/84.sql | 2 +- .../MergeResourcesDeleteInvisibleHistory.sql | 4 +- 3 files changed, 90 insertions(+), 10 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql index 148810f8e6..ec32791dc0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -595,7 +595,7 @@ END COMMIT TRANSACTION END GO -BEGIN TRANSACTION +BEGIN TRANSACTION -- update ReferenceSearchParamList GO DROP PROCEDURE CaptureResourceIdsForChanges DROP PROCEDURE MergeResources @@ -1527,6 +1527,8 @@ END CATCH GO COMMIT TRANSACTION GO +-- Special versions of procedures for data movement +GO ALTER PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId bigint, @AffectedRows int = NULL OUT AS set nocount on @@ -1535,20 +1537,34 @@ DECLARE @SP varchar(100) = object_name(@@procid) ,@st datetime ,@Rows int ,@DeletedIdMap int + ,@TypeId smallint SET @AffectedRows = 0 +DECLARE @Types TABLE (TypeId smallint PRIMARY KEY, Name varchar(100)) +INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes + +DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + Retry: BEGIN TRY - DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) - + WHILE EXISTS (SELECT * FROM @Types) + BEGIN + SET @TypeId = (SELECT TOP 1 TypeId FROM @Types ORDER BY TypeId) + + DELETE FROM dbo.ResourceTbl WHERE ResourceTypeId = @TypeId AND HistoryTransactionId = @TransactionId AND RawResource = 0xF + SET @AffectedRows += @@rowcount + + DELETE FROM @Types WHERE TypeId = @TypeId + END + BEGIN TRANSACTION SET @st = getUTCdate() DELETE FROM A OUTPUT deleted.ResourceTypeId, deleted.ResourceIdInt INTO @Ids FROM dbo.Resource A - WHERE HistoryTransactionId = @TransactionId + WHERE HistoryTransactionId = @TransactionId -- requires statistics to reflect not null values SET @Rows = @@rowcount EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@Rows SET @AffectedRows += @Rows @@ -1571,8 +1587,8 @@ BEGIN TRY SET @DeletedIdMap = @@rowcount END END + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap END - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap COMMIT TRANSACTION @@ -1593,8 +1609,6 @@ BEGIN CATCH THROW END CATCH GO --- Special versions of procedures for data movement -GO ALTER PROCEDURE dbo.GetResourcesByTransactionId @TransactionId bigint, @IncludeHistory bit = 0, @ReturnResourceKeysOnly bit = 0 AS set nocount on @@ -3457,6 +3471,72 @@ BEGIN CATCH THROW END CATCH GO +ALTER PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId bigint, @AffectedRows int = NULL OUT +AS +set nocount on +DECLARE @SP varchar(100) = object_name(@@procid) + ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId) + ,@st datetime + ,@Rows int + ,@DeletedIdMap int + +SET @AffectedRows = 0 + +Retry: +BEGIN TRY + DECLARE @Ids TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) + + BEGIN TRANSACTION + + SET @st = getUTCdate() + DELETE FROM A + OUTPUT deleted.ResourceTypeId, deleted.ResourceIdInt INTO @Ids + FROM dbo.Resource A + WHERE HistoryTransactionId = @TransactionId -- requires updated statistics + SET @Rows = @@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@Rows + SET @AffectedRows += @Rows + + SET @st = getUTCdate() + IF @Rows > 0 + BEGIN + -- remove referenced in resources + DELETE FROM A FROM @Ids A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + -- remove referenced in reference search params + DELETE FROM A FROM @Ids A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = A.ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) + SET @Rows -= @@rowcount + IF @Rows > 0 + BEGIN + -- delete from id map + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + SET @DeletedIdMap = @@rowcount + END + END + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap + END + + COMMIT TRANSACTION + + SET @st = getUTCdate() + UPDATE dbo.Resource SET TransactionId = NULL WHERE TransactionId = @TransactionId + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Target='Resource',@Action='Update',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + IF @@trancount > 0 ROLLBACK TRANSACTION + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error' + IF error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @Ids + GOTO Retry + END + ELSE + THROW +END CATCH +GO --DROP TABLE IF EXISTS ResourceTbl -- TODO: Remove table after deployment GO --DROP TABLE IF EXISTS ReferenceSearchParamTbl -- TODO: Remove table after deployment diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql index a11ab332d5..f24d3f5c5e 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -4997,8 +4997,8 @@ BEGIN TRY SET @DeletedIdMap = @@rowcount; END END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'ResourceIdIntMap', @Action = 'Delete', @Start = @st, @Rows = @DeletedIdMap; END - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'ResourceIdIntMap', @Action = 'Delete', @Start = @st, @Rows = @DeletedIdMap; COMMIT TRANSACTION; SET @st = getUTCdate(); UPDATE dbo.Resource diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql index 159000e740..827e38268a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql @@ -21,7 +21,7 @@ BEGIN TRY DELETE FROM A OUTPUT deleted.ResourceTypeId, deleted.ResourceIdInt INTO @Ids FROM dbo.Resource A - WHERE HistoryTransactionId = @TransactionId + WHERE HistoryTransactionId = @TransactionId -- requires updated statistics SET @Rows = @@rowcount EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@Rows SET @AffectedRows += @Rows @@ -44,8 +44,8 @@ BEGIN TRY SET @DeletedIdMap = @@rowcount END END + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap END - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap COMMIT TRANSACTION From 9197191de142582778eb9d5fee0f0434656d2668 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 15:12:30 -0800 Subject: [PATCH 052/111] DataLakeStore flag --- .../Storage/{SqlAdlsStore.cs => SqlDataLakeStore.cs} | 4 ++-- .../Features/Storage/SqlServerFhirDataStore.cs | 8 ++++---- .../Features/Storage/SqlStoreClient.cs | 6 +++--- 3 files changed, 9 insertions(+), 9 deletions(-) rename src/Microsoft.Health.Fhir.SqlServer/Features/Storage/{SqlAdlsStore.cs => SqlDataLakeStore.cs} (97%) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlDataLakeStore.cs similarity index 97% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsStore.cs rename to src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlDataLakeStore.cs index 3987e3a43a..1140753794 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlDataLakeStore.cs @@ -13,7 +13,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Storage { - internal class SqlAdlsStore + internal class SqlDataLakeStore { private static readonly object _parameterLocker = new object(); private static string _adlsContainer; @@ -25,7 +25,7 @@ internal class SqlAdlsStore private static BlobContainerClient _adlsClient; private static bool _adlsIsSet; - public SqlAdlsStore(ISqlRetryService sqlRetryService, ILogger logger) + public SqlDataLakeStore(ISqlRetryService sqlRetryService, ILogger logger) { EnsureArg.IsNotNull(sqlRetryService, nameof(sqlRetryService)); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index af52edca31..a1c23fa05b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -124,7 +124,7 @@ public SqlServerFhirDataStore( } } - _ = new SqlAdlsStore(_sqlRetryService, _logger); + _ = new SqlDataLakeStore(_sqlRetryService, _logger); } internal SqlStoreClient StoreClient => _sqlStoreClient; @@ -140,7 +140,7 @@ private async Task PutRawResourcesIntoAdls(IReadOnlyList r retry: try { - using var stream = await SqlAdlsStore.AdlsClient.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); + using var stream = await SqlDataLakeStore.AdlsClient.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); using var writer = new StreamWriter(stream); var offset = 0; foreach (var resource in resources) @@ -763,7 +763,7 @@ internal async Task MergeResourcesWrapperAsync(long transactionId, bool singleTr cmd.Parameters.AddWithValue("@IsResourceChangeCaptureEnabled", _coreFeatures.SupportsResourceChangeCapture); cmd.Parameters.AddWithValue("@TransactionId", transactionId); cmd.Parameters.AddWithValue("@SingleTransaction", singleTransaction); - if (_schemaInformation.Current >= SchemaVersionConstants.Lake && SqlAdlsStore.AdlsClient != null) + if (_schemaInformation.Current >= SchemaVersionConstants.Lake && SqlDataLakeStore.AdlsClient != null) { await PutRawResourcesIntoAdls(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource } @@ -838,7 +838,7 @@ public async Task GetAsync(ResourceKey key, CancellationToken c public async Task HardDeleteAsync(ResourceKey key, bool keepCurrentVersion, bool allowPartialSuccess, CancellationToken cancellationToken) { - var makeResourceInvisible = _coreFeatures.SupportsResourceChangeCapture; // TODO: For case when Raw in Lake are supported, this should be true. + var makeResourceInvisible = _coreFeatures.SupportsResourceChangeCapture || SqlDataLakeStore.AdlsClient != null; await _sqlStoreClient.HardDeleteAsync(_model.GetResourceTypeId(key.ResourceType), key.Id, keepCurrentVersion, makeResourceInvisible, cancellationToken); } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 776a1aac80..ffacfe8512 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -77,7 +77,7 @@ public async Task> GetAsync(IReadOnlyList { return ReadResourceWrapper(reader, false, decompress, SqlAdlsStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, false, decompress, SqlDataLakeStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); } catch (Exception e) { @@ -99,7 +99,7 @@ public static Lazy GetRawResourceFromAdls(long fileId, int offsetInFile) return new Lazy(() => { var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(fileId); - using var reader = new StreamReader(SqlAdlsStore.AdlsClient.GetBlobClient(blobName).OpenRead(offsetInFile)); + using var reader = new StreamReader(SqlDataLakeStore.AdlsClient.GetBlobClient(blobName).OpenRead(offsetInFile)); var line = reader.ReadLine(); return line; }); @@ -168,7 +168,7 @@ internal async Task> GetResourcesByTransactionIdA await using var cmd = new SqlCommand() { CommandText = "dbo.GetResourcesByTransactionId", CommandType = CommandType.StoredProcedure, CommandTimeout = 600 }; cmd.Parameters.AddWithValue("@TransactionId", transactionId); //// ignore invisible resources - return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlAdlsStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlDataLakeStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); } private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func decompress, BlobContainerClient adlsClient, Func getResourceTypeName) From 4183235dc8a8f5f9d9c3a023b54bbd167caeb7d6 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 16:17:44 -0800 Subject: [PATCH 053/111] names --- .../Storage/{SqlDataLakeStore.cs => SqlAdlsCient.cs} | 10 +++++----- .../Features/Storage/SqlServerFhirDataStore.cs | 8 ++++---- .../Features/Storage/SqlStoreClient.cs | 6 +++--- 3 files changed, 12 insertions(+), 12 deletions(-) rename src/Microsoft.Health.Fhir.SqlServer/Features/Storage/{SqlDataLakeStore.cs => SqlAdlsCient.cs} (92%) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlDataLakeStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs similarity index 92% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlDataLakeStore.cs rename to src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs index 1140753794..d272c193e2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlDataLakeStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs @@ -13,7 +13,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Storage { - internal class SqlDataLakeStore + internal class SqlAdlsCient { private static readonly object _parameterLocker = new object(); private static string _adlsContainer; @@ -25,7 +25,7 @@ internal class SqlDataLakeStore private static BlobContainerClient _adlsClient; private static bool _adlsIsSet; - public SqlDataLakeStore(ISqlRetryService sqlRetryService, ILogger logger) + public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) { EnsureArg.IsNotNull(sqlRetryService, nameof(sqlRetryService)); @@ -55,7 +55,7 @@ public SqlDataLakeStore(ISqlRetryService sqlRetryService, ILogger logger) if (_adlsConnectionString != null || _adlsAccountUri != null) { - _adlsClient = GetAdlsContainer(); + _adlsClient = GetContainer(); } _adlsIsSet = true; @@ -64,7 +64,7 @@ public SqlDataLakeStore(ISqlRetryService sqlRetryService, ILogger logger) } } - public static BlobContainerClient AdlsClient => _adlsIsSet ? _adlsClient : throw new ArgumentOutOfRangeException(); + public static BlobContainerClient Container => _adlsIsSet ? _adlsClient : throw new ArgumentOutOfRangeException(); public static string AdlsContainer => _adlsIsSet ? _adlsContainer : throw new ArgumentOutOfRangeException(); @@ -91,7 +91,7 @@ private static string GetStorageParameter(ISqlRetryService sqlRetryService, ILog } } - private static BlobContainerClient GetAdlsContainer() // creates if does not exist + private static BlobContainerClient GetContainer() // creates if does not exist { var blobContainerClient = _adlsAccountUri != null && _adlsAccountManagedIdentityClientId != null ? new BlobContainerClient(new Uri(_adlsAccountUri, _adlsContainer), new ManagedIdentityCredential(_adlsAccountManagedIdentityClientId)) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index a1c23fa05b..c07c317b0d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -124,7 +124,7 @@ public SqlServerFhirDataStore( } } - _ = new SqlDataLakeStore(_sqlRetryService, _logger); + _ = new SqlAdlsCient(_sqlRetryService, _logger); } internal SqlStoreClient StoreClient => _sqlStoreClient; @@ -140,7 +140,7 @@ private async Task PutRawResourcesIntoAdls(IReadOnlyList r retry: try { - using var stream = await SqlDataLakeStore.AdlsClient.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); + using var stream = await SqlAdlsCient.Container.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); using var writer = new StreamWriter(stream); var offset = 0; foreach (var resource in resources) @@ -763,7 +763,7 @@ internal async Task MergeResourcesWrapperAsync(long transactionId, bool singleTr cmd.Parameters.AddWithValue("@IsResourceChangeCaptureEnabled", _coreFeatures.SupportsResourceChangeCapture); cmd.Parameters.AddWithValue("@TransactionId", transactionId); cmd.Parameters.AddWithValue("@SingleTransaction", singleTransaction); - if (_schemaInformation.Current >= SchemaVersionConstants.Lake && SqlDataLakeStore.AdlsClient != null) + if (_schemaInformation.Current >= SchemaVersionConstants.Lake && SqlAdlsCient.Container != null) { await PutRawResourcesIntoAdls(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource } @@ -838,7 +838,7 @@ public async Task GetAsync(ResourceKey key, CancellationToken c public async Task HardDeleteAsync(ResourceKey key, bool keepCurrentVersion, bool allowPartialSuccess, CancellationToken cancellationToken) { - var makeResourceInvisible = _coreFeatures.SupportsResourceChangeCapture || SqlDataLakeStore.AdlsClient != null; + var makeResourceInvisible = _coreFeatures.SupportsResourceChangeCapture || SqlAdlsCient.Container != null; await _sqlStoreClient.HardDeleteAsync(_model.GetResourceTypeId(key.ResourceType), key.Id, keepCurrentVersion, makeResourceInvisible, cancellationToken); } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index ffacfe8512..97b9e2fd2c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -77,7 +77,7 @@ public async Task> GetAsync(IReadOnlyList { return ReadResourceWrapper(reader, false, decompress, SqlDataLakeStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, false, decompress, SqlAdlsCient.Container, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); } catch (Exception e) { @@ -99,7 +99,7 @@ public static Lazy GetRawResourceFromAdls(long fileId, int offsetInFile) return new Lazy(() => { var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(fileId); - using var reader = new StreamReader(SqlDataLakeStore.AdlsClient.GetBlobClient(blobName).OpenRead(offsetInFile)); + using var reader = new StreamReader(SqlAdlsCient.Container.GetBlobClient(blobName).OpenRead(offsetInFile)); var line = reader.ReadLine(); return line; }); @@ -168,7 +168,7 @@ internal async Task> GetResourcesByTransactionIdA await using var cmd = new SqlCommand() { CommandText = "dbo.GetResourcesByTransactionId", CommandType = CommandType.StoredProcedure, CommandTimeout = 600 }; cmd.Parameters.AddWithValue("@TransactionId", transactionId); //// ignore invisible resources - return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlDataLakeStore.AdlsClient, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); + return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlAdlsCient.Container, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); } private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func decompress, BlobContainerClient adlsClient, Func getResourceTypeName) From 0347536f487666e897aed7e136cc19e994d85b91 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 16:21:20 -0800 Subject: [PATCH 054/111] names --- .../Features/Storage/SqlAdlsCient.cs | 18 +++++++++--------- 1 file changed, 9 insertions(+), 9 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs index d272c193e2..e40783ac26 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs @@ -16,13 +16,13 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Storage internal class SqlAdlsCient { private static readonly object _parameterLocker = new object(); - private static string _adlsContainer; + private static string _adlsContainerName; private static string _adlsConnectionString; private static string _adlsAccountName; private static string _adlsAccountKey; private static Uri _adlsAccountUri; private static string _adlsAccountManagedIdentityClientId; - private static BlobContainerClient _adlsClient; + private static BlobContainerClient _adlsContainer; private static bool _adlsIsSet; public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) @@ -44,7 +44,7 @@ public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) } var db = sqlRetryService.Database.Length < 50 ? sqlRetryService.Database : sqlRetryService.Database.Substring(0, 50); - _adlsContainer = $"fhir-adls-{db.Replace("_", "-", StringComparison.InvariantCultureIgnoreCase).ToLowerInvariant()}"; + _adlsContainerName = $"fhir-adls-{db.Replace("_", "-", StringComparison.InvariantCultureIgnoreCase).ToLowerInvariant()}"; var uriStr = GetStorageParameter(sqlRetryService, logger, "MergeResources.AdlsAccountUri"); if (uriStr != null) @@ -55,7 +55,7 @@ public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) if (_adlsConnectionString != null || _adlsAccountUri != null) { - _adlsClient = GetContainer(); + _adlsContainer = GetContainer(); } _adlsIsSet = true; @@ -64,9 +64,9 @@ public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) } } - public static BlobContainerClient Container => _adlsIsSet ? _adlsClient : throw new ArgumentOutOfRangeException(); + public static BlobContainerClient Container => _adlsIsSet ? _adlsContainer : throw new ArgumentOutOfRangeException(); - public static string AdlsContainer => _adlsIsSet ? _adlsContainer : throw new ArgumentOutOfRangeException(); + public static string AdlsContainerName => _adlsIsSet ? _adlsContainerName : throw new ArgumentOutOfRangeException(); public static string AdlsAccountName => _adlsIsSet ? _adlsAccountName : throw new ArgumentOutOfRangeException(); @@ -94,10 +94,10 @@ private static string GetStorageParameter(ISqlRetryService sqlRetryService, ILog private static BlobContainerClient GetContainer() // creates if does not exist { var blobContainerClient = _adlsAccountUri != null && _adlsAccountManagedIdentityClientId != null - ? new BlobContainerClient(new Uri(_adlsAccountUri, _adlsContainer), new ManagedIdentityCredential(_adlsAccountManagedIdentityClientId)) + ? new BlobContainerClient(new Uri(_adlsAccountUri, _adlsContainerName), new ManagedIdentityCredential(_adlsAccountManagedIdentityClientId)) : _adlsAccountUri != null - ? new BlobContainerClient(new Uri(_adlsAccountUri, _adlsContainer), new InteractiveBrowserCredential()) - : new BlobServiceClient(_adlsConnectionString).GetBlobContainerClient(_adlsContainer); + ? new BlobContainerClient(new Uri(_adlsAccountUri, _adlsContainerName), new InteractiveBrowserCredential()) + : new BlobServiceClient(_adlsConnectionString).GetBlobContainerClient(_adlsContainerName); if (!blobContainerClient.Exists()) { From ba9415b1981b680ed2fe1b66ee0e6c1218d48aab Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 17:18:36 -0800 Subject: [PATCH 055/111] Current resource view --- .../Features/Schema/Migrations/84.diff.sql | 6 + .../Features/Schema/Migrations/84.sql | 5176 +++++++++++++++++ .../Features/Schema/SchemaVersion.cs | 1 + .../Features/Schema/SchemaVersionConstants.cs | 7 +- .../TransactionCheckWithInitialiScript.sql | 2 +- .../Tables/{Resource.sql => Resource_0.sql} | 21 +- .../Schema/Sql/Views/CurrentResource.sql | 6 + .../QueryGenerators/SqlQueryGenerator.cs | 32 +- .../Microsoft.Health.Fhir.SqlServer.csproj | 3 +- 9 files changed, 5237 insertions(+), 17 deletions(-) create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql rename src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/{Resource.sql => Resource_0.sql} (71%) create mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql new file mode 100644 index 0000000000..ba0f508157 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql @@ -0,0 +1,6 @@ +CREATE OR ALTER VIEW dbo.CurrentResource +AS +SELECT * + FROM dbo.Resource + WHERE IsHistory = 0 +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql new file mode 100644 index 0000000000..5363ac4c7c --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql @@ -0,0 +1,5176 @@ + +/************************************************************************************************* + Auto-Generated from Sql build task. Do not manually edit it. +**************************************************************************************************/ +SET XACT_ABORT ON +BEGIN TRAN +IF EXISTS (SELECT * + FROM sys.tables + WHERE name = 'ClaimType') + BEGIN + ROLLBACK; + RETURN; + END + + +GO +INSERT INTO dbo.SchemaVersion +VALUES (84, 'started'); + +CREATE PARTITION FUNCTION PartitionFunction_ResourceTypeId(SMALLINT) + AS RANGE RIGHT + FOR VALUES (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150); + +CREATE PARTITION SCHEME PartitionScheme_ResourceTypeId + AS PARTITION PartitionFunction_ResourceTypeId + ALL TO ([PRIMARY]); + + +GO +CREATE PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp(DATETIME2 (7)) + AS RANGE RIGHT + FOR VALUES (N'1970-01-01T00:00:00.0000000'); + +CREATE PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp + AS PARTITION PartitionFunction_ResourceChangeData_Timestamp + ALL TO ([PRIMARY]); + +DECLARE @numberOfHistoryPartitions AS INT = 48; + +DECLARE @numberOfFuturePartitions AS INT = 720; + +DECLARE @rightPartitionBoundary AS DATETIME2 (7); + +DECLARE @currentDateTime AS DATETIME2 (7) = sysutcdatetime(); + +WHILE @numberOfHistoryPartitions >= -@numberOfFuturePartitions + BEGIN + SET @rightPartitionBoundary = DATEADD(hour, DATEDIFF(hour, 0, @currentDateTime) - @numberOfHistoryPartitions, 0); + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [Primary]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@rightPartitionBoundary); + SET @numberOfHistoryPartitions -= 1; + END + +CREATE SEQUENCE dbo.ResourceSurrogateIdUniquifierSequence + AS INT + START WITH 0 + INCREMENT BY 1 + MINVALUE 0 + MAXVALUE 79999 + CYCLE + CACHE 1000000; + +CREATE TYPE dbo.BigintList AS TABLE ( + Id BIGINT NOT NULL PRIMARY KEY); + +CREATE TYPE dbo.DateTimeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + StartDateTime DATETIMEOFFSET (7) NOT NULL, + EndDateTime DATETIMEOFFSET (7) NOT NULL, + IsLongerThanADay BIT NOT NULL, + IsMin BIT NOT NULL, + IsMax BIT NOT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax)); + +CREATE TYPE dbo.NumberSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NULL, + HighValue DECIMAL (36, 18) NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue)); + +CREATE TYPE dbo.QuantitySearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + QuantityCodeId INT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NULL, + HighValue DECIMAL (36, 18) NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue)); + +CREATE TYPE dbo.ReferenceSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion INT NULL UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId)); + +CREATE TYPE dbo.ReferenceTokenCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri1 VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId1 SMALLINT NULL, + ReferenceResourceId1 VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion1 INT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.ResourceDateKeyList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ResourceSurrogateId BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId, ResourceSurrogateId)); + +CREATE TYPE dbo.ResourceKeyList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NULL UNIQUE (ResourceTypeId, ResourceId, Version)); + +CREATE TYPE dbo.ResourceList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + HasVersionToCompare BIT NOT NULL, + IsDeleted BIT NOT NULL, + IsHistory BIT NOT NULL, + KeepHistory BIT NOT NULL, + RawResource VARBINARY (MAX) NOT NULL, + IsRawResourceMetaSet BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + SearchParamHash VARCHAR (64) NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId), + UNIQUE (ResourceTypeId, ResourceId, Version)); + +CREATE TYPE dbo.ResourceWriteClaimList AS TABLE ( + ResourceSurrogateId BIGINT NOT NULL, + ClaimTypeId TINYINT NOT NULL, + ClaimValue NVARCHAR (128) NOT NULL); + +CREATE TYPE dbo.StringList AS TABLE ( + String VARCHAR (MAX)); + +CREATE TYPE dbo.StringSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL, + IsMin BIT NOT NULL, + IsMax BIT NOT NULL); + +CREATE TYPE dbo.TokenDateTimeCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + StartDateTime2 DATETIMEOFFSET (7) NOT NULL, + EndDateTime2 DATETIMEOFFSET (7) NOT NULL, + IsLongerThanADay2 BIT NOT NULL); + +CREATE TYPE dbo.TokenNumberNumberCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + SingleValue3 DECIMAL (36, 18) NULL, + LowValue3 DECIMAL (36, 18) NULL, + HighValue3 DECIMAL (36, 18) NULL, + HasRange BIT NOT NULL); + +CREATE TYPE dbo.TokenQuantityCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SystemId2 INT NULL, + QuantityCodeId2 INT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL); + +CREATE TYPE dbo.TokenSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + Code VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.TokenStringCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + Text2 NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow2 NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL); + +CREATE TYPE dbo.TokenTextList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (400) COLLATE Latin1_General_CI_AI NOT NULL); + +CREATE TYPE dbo.TokenTokenCompositeSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL); + +CREATE TYPE dbo.SearchParamTableType_2 AS TABLE ( + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (20) NOT NULL, + IsPartiallySupported BIT NOT NULL); + +CREATE TYPE dbo.BulkReindexResourceTableType_1 AS TABLE ( + Offset INT NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ETag INT NULL, + SearchParamHash VARCHAR (64) NOT NULL); + +CREATE TYPE dbo.UriSearchParamList AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri)); + +CREATE TABLE dbo.ClaimType ( + ClaimTypeId TINYINT IDENTITY (1, 1) NOT NULL, + Name VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_ClaimType_ClaimTypeId UNIQUE (ClaimTypeId), + CONSTRAINT PKC_ClaimType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.CompartmentAssignment ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + CompartmentTypeId TINYINT NOT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + IsHistory BIT NOT NULL, + CONSTRAINT PKC_CompartmentAssignment PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId, CompartmentTypeId, ReferenceResourceId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +); + + +GO +ALTER TABLE dbo.CompartmentAssignment + ADD CONSTRAINT DF_CompartmentAssignment_IsHistory DEFAULT 0 FOR IsHistory; + + +GO +ALTER TABLE dbo.CompartmentAssignment SET (LOCK_ESCALATION = AUTO); + + +GO +CREATE NONCLUSTERED INDEX IX_CompartmentAssignment_CompartmentTypeId_ReferenceResourceId + ON dbo.CompartmentAssignment(ResourceTypeId, CompartmentTypeId, ReferenceResourceId, ResourceSurrogateId) WHERE IsHistory = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.CompartmentType ( + CompartmentTypeId TINYINT IDENTITY (1, 1) NOT NULL, + Name VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_CompartmentType_CompartmentTypeId UNIQUE (CompartmentTypeId), + CONSTRAINT PKC_CompartmentType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.DateTimeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + StartDateTime DATETIME2 (7) NOT NULL, + EndDateTime DATETIME2 (7) NOT NULL, + IsLongerThanADay BIT NOT NULL, + IsMin BIT CONSTRAINT date_IsMin_Constraint DEFAULT 0 NOT NULL, + IsMax BIT CONSTRAINT date_IsMax_Constraint DEFAULT 0 NOT NULL +); + +ALTER TABLE dbo.DateTimeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_DateTimeSearchParam + ON dbo.DateTimeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_StartDateTime_EndDateTime_INCLUDE_IsLongerThanADay_IsMin_IsMax + ON dbo.DateTimeSearchParam(SearchParamId, StartDateTime, EndDateTime) + INCLUDE(IsLongerThanADay, IsMin, IsMax) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_EndDateTime_StartDateTime_INCLUDE_IsLongerThanADay_IsMin_IsMax + ON dbo.DateTimeSearchParam(SearchParamId, EndDateTime, StartDateTime) + INCLUDE(IsLongerThanADay, IsMin, IsMax) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_StartDateTime_EndDateTime_INCLUDE_IsMin_IsMax_WHERE_IsLongerThanADay_1 + ON dbo.DateTimeSearchParam(SearchParamId, StartDateTime, EndDateTime) + INCLUDE(IsMin, IsMax) WHERE IsLongerThanADay = 1 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_EndDateTime_StartDateTime_INCLUDE_IsMin_IsMax_WHERE_IsLongerThanADay_1 + ON dbo.DateTimeSearchParam(SearchParamId, EndDateTime, StartDateTime) + INCLUDE(IsMin, IsMax) WHERE IsLongerThanADay = 1 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +IF NOT EXISTS (SELECT 1 + FROM sys.tables + WHERE name = 'EventAgentCheckpoint') + BEGIN + CREATE TABLE dbo.EventAgentCheckpoint ( + CheckpointId VARCHAR (64) NOT NULL, + LastProcessedDateTime DATETIMEOFFSET (7), + LastProcessedIdentifier VARCHAR (64) , + UpdatedOn DATETIME2 (7) DEFAULT sysutcdatetime() NOT NULL, + CONSTRAINT PK_EventAgentCheckpoint PRIMARY KEY CLUSTERED (CheckpointId) + ) ON [PRIMARY]; + END + +CREATE PARTITION FUNCTION EventLogPartitionFunction(TINYINT) + AS RANGE RIGHT + FOR VALUES (0, 1, 2, 3, 4, 5, 6, 7); + + +GO +CREATE PARTITION SCHEME EventLogPartitionScheme + AS PARTITION EventLogPartitionFunction + ALL TO ([PRIMARY]); + + +GO +CREATE TABLE dbo.EventLog ( + PartitionId AS isnull(CONVERT (TINYINT, EventId % 8), 0) PERSISTED, + EventId BIGINT IDENTITY (1, 1) NOT NULL, + EventDate DATETIME NOT NULL, + Process VARCHAR (100) NOT NULL, + Status VARCHAR (10) NOT NULL, + Mode VARCHAR (200) NULL, + Action VARCHAR (20) NULL, + Target VARCHAR (100) NULL, + Rows BIGINT NULL, + Milliseconds INT NULL, + EventText NVARCHAR (3500) NULL, + SPID SMALLINT NOT NULL, + HostName VARCHAR (64) NOT NULL CONSTRAINT PKC_EventLog_EventDate_EventId_PartitionId PRIMARY KEY CLUSTERED (EventDate, EventId, PartitionId) ON EventLogPartitionScheme (PartitionId) +); + +CREATE TABLE dbo.ExportJob ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Hash VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (10) NOT NULL, + HeartbeatDateTime DATETIME2 (7) NULL, + RawJobRecord VARCHAR (MAX) NOT NULL, + JobVersion ROWVERSION NOT NULL, + CONSTRAINT PKC_ExportJob PRIMARY KEY CLUSTERED (Id) +); + +CREATE UNIQUE NONCLUSTERED INDEX IX_ExportJob_Hash_Status_HeartbeatDateTime + ON dbo.ExportJob(Hash, Status, HeartbeatDateTime); + +CREATE TABLE dbo.IndexProperties ( + TableName VARCHAR (100) NOT NULL, + IndexName VARCHAR (200) NOT NULL, + PropertyName VARCHAR (100) NOT NULL, + PropertyValue VARCHAR (100) NOT NULL, + CreateDate DATETIME CONSTRAINT DF_IndexProperties_CreateDate DEFAULT getUTCdate() NOT NULL CONSTRAINT PKC_IndexProperties_TableName_IndexName_PropertyName PRIMARY KEY CLUSTERED (TableName, IndexName, PropertyName) +); + +CREATE PARTITION FUNCTION TinyintPartitionFunction(TINYINT) + AS RANGE RIGHT + FOR VALUES (0, 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11, 12, 13, 14, 15, 16, 17, 18, 19, 20, 21, 22, 23, 24, 25, 26, 27, 28, 29, 30, 31, 32, 33, 34, 35, 36, 37, 38, 39, 40, 41, 42, 43, 44, 45, 46, 47, 48, 49, 50, 51, 52, 53, 54, 55, 56, 57, 58, 59, 60, 61, 62, 63, 64, 65, 66, 67, 68, 69, 70, 71, 72, 73, 74, 75, 76, 77, 78, 79, 80, 81, 82, 83, 84, 85, 86, 87, 88, 89, 90, 91, 92, 93, 94, 95, 96, 97, 98, 99, 100, 101, 102, 103, 104, 105, 106, 107, 108, 109, 110, 111, 112, 113, 114, 115, 116, 117, 118, 119, 120, 121, 122, 123, 124, 125, 126, 127, 128, 129, 130, 131, 132, 133, 134, 135, 136, 137, 138, 139, 140, 141, 142, 143, 144, 145, 146, 147, 148, 149, 150, 151, 152, 153, 154, 155, 156, 157, 158, 159, 160, 161, 162, 163, 164, 165, 166, 167, 168, 169, 170, 171, 172, 173, 174, 175, 176, 177, 178, 179, 180, 181, 182, 183, 184, 185, 186, 187, 188, 189, 190, 191, 192, 193, 194, 195, 196, 197, 198, 199, 200, 201, 202, 203, 204, 205, 206, 207, 208, 209, 210, 211, 212, 213, 214, 215, 216, 217, 218, 219, 220, 221, 222, 223, 224, 225, 226, 227, 228, 229, 230, 231, 232, 233, 234, 235, 236, 237, 238, 239, 240, 241, 242, 243, 244, 245, 246, 247, 248, 249, 250, 251, 252, 253, 254, 255); + + +GO +CREATE PARTITION SCHEME TinyintPartitionScheme + AS PARTITION TinyintPartitionFunction + ALL TO ([PRIMARY]); + + +GO +CREATE TABLE dbo.JobQueue ( + QueueType TINYINT NOT NULL, + GroupId BIGINT NOT NULL, + JobId BIGINT NOT NULL, + PartitionId AS CONVERT (TINYINT, JobId % 16) PERSISTED, + Definition VARCHAR (MAX) NOT NULL, + DefinitionHash VARBINARY (20) NOT NULL, + Version BIGINT CONSTRAINT DF_JobQueue_Version DEFAULT datediff_big(millisecond, '0001-01-01', getUTCdate()) NOT NULL, + Status TINYINT CONSTRAINT DF_JobQueue_Status DEFAULT 0 NOT NULL, + Priority TINYINT CONSTRAINT DF_JobQueue_Priority DEFAULT 100 NOT NULL, + Data BIGINT NULL, + Result VARCHAR (MAX) NULL, + CreateDate DATETIME CONSTRAINT DF_JobQueue_CreateDate DEFAULT getUTCdate() NOT NULL, + StartDate DATETIME NULL, + EndDate DATETIME NULL, + HeartbeatDate DATETIME CONSTRAINT DF_JobQueue_HeartbeatDate DEFAULT getUTCdate() NOT NULL, + Worker VARCHAR (100) NULL, + Info VARCHAR (1000) NULL, + CancelRequested BIT CONSTRAINT DF_JobQueue_CancelRequested DEFAULT 0 NOT NULL CONSTRAINT PKC_JobQueue_QueueType_PartitionId_JobId PRIMARY KEY CLUSTERED (QueueType, PartitionId, JobId) ON TinyintPartitionScheme (QueueType), + CONSTRAINT U_JobQueue_QueueType_JobId UNIQUE (QueueType, JobId) +); + + +GO +CREATE INDEX IX_QueueType_PartitionId_Status_Priority + ON dbo.JobQueue(PartitionId, Status, Priority) + ON TinyintPartitionScheme (QueueType); + + +GO +CREATE INDEX IX_QueueType_GroupId + ON dbo.JobQueue(QueueType, GroupId) + ON TinyintPartitionScheme (QueueType); + + +GO +CREATE INDEX IX_QueueType_DefinitionHash + ON dbo.JobQueue(QueueType, DefinitionHash) + ON TinyintPartitionScheme (QueueType); + +CREATE TABLE dbo.NumberSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NOT NULL, + HighValue DECIMAL (36, 18) NOT NULL +); + +ALTER TABLE dbo.NumberSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_NumberSearchParam + ON dbo.NumberSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_SingleValue_WHERE_SingleValue_NOT_NULL + ON dbo.NumberSearchParam(SearchParamId, SingleValue) WHERE SingleValue IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_LowValue_HighValue + ON dbo.NumberSearchParam(SearchParamId, LowValue, HighValue) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_HighValue_LowValue + ON dbo.NumberSearchParam(SearchParamId, HighValue, LowValue) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.Parameters ( + Id VARCHAR (100) NOT NULL, + Date DATETIME NULL, + Number FLOAT NULL, + Bigint BIGINT NULL, + Char VARCHAR (4000) NULL, + Binary VARBINARY (MAX) NULL, + UpdatedDate DATETIME NULL, + UpdatedBy NVARCHAR (255) NULL CONSTRAINT PKC_Parameters_Id PRIMARY KEY CLUSTERED (Id) WITH (IGNORE_DUP_KEY = ON) +); + + +GO +CREATE TABLE dbo.ParametersHistory ( + ChangeId INT IDENTITY (1, 1) NOT NULL, + Id VARCHAR (100) NOT NULL, + Date DATETIME NULL, + Number FLOAT NULL, + Bigint BIGINT NULL, + Char VARCHAR (4000) NULL, + Binary VARBINARY (MAX) NULL, + UpdatedDate DATETIME NULL, + UpdatedBy NVARCHAR (255) NULL +); + +CREATE TABLE dbo.QuantityCode ( + QuantityCodeId INT IDENTITY (1, 1) NOT NULL, + Value NVARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_QuantityCode_QuantityCodeId UNIQUE (QuantityCodeId), + CONSTRAINT PKC_QuantityCode PRIMARY KEY CLUSTERED (Value) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.QuantitySearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + QuantityCodeId INT NULL, + SingleValue DECIMAL (36, 18) NULL, + LowValue DECIMAL (36, 18) NOT NULL, + HighValue DECIMAL (36, 18) NOT NULL +); + +ALTER TABLE dbo.QuantitySearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_QuantitySearchParam + ON dbo.QuantitySearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_SingleValue_INCLUDE_SystemId_WHERE_SingleValue_NOT_NULL + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, SingleValue) + INCLUDE(SystemId) WHERE SingleValue IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_LowValue_HighValue_INCLUDE_SystemId + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, LowValue, HighValue) + INCLUDE(SystemId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_QuantityCodeId_HighValue_LowValue_INCLUDE_SystemId + ON dbo.QuantitySearchParam(SearchParamId, QuantityCodeId, HighValue, LowValue) + INCLUDE(SystemId) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReferenceSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId SMALLINT NULL, + ReferenceResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion INT NULL +); + +ALTER TABLE dbo.ReferenceSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_ReferenceSearchParam + ON dbo.ReferenceSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE INDEX IXU_ReferenceResourceId_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.ReferenceSearchParam(ReferenceResourceId, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReferenceTokenCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + BaseUri1 VARCHAR (128) COLLATE Latin1_General_100_CS_AS NULL, + ReferenceResourceTypeId1 SMALLINT NULL, + ReferenceResourceId1 VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ReferenceResourceVersion1 INT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.ReferenceTokenCompositeSearchParam + ADD CONSTRAINT CHK_ReferenceTokenCompositeSearchParam_CodeOverflow2 CHECK (LEN(Code2) = 256 + OR CodeOverflow2 IS NULL); + +ALTER TABLE dbo.ReferenceTokenCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_ReferenceTokenCompositeSearchParam + ON dbo.ReferenceTokenCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_ReferenceResourceId1_Code2_INCLUDE_ReferenceResourceTypeId1_BaseUri1_SystemId2 + ON dbo.ReferenceTokenCompositeSearchParam(SearchParamId, ReferenceResourceId1, Code2) + INCLUDE(ReferenceResourceTypeId1, BaseUri1, SystemId2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.ReindexJob ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (10) NOT NULL, + HeartbeatDateTime DATETIME2 (7) NULL, + RawJobRecord VARCHAR (MAX) NOT NULL, + JobVersion ROWVERSION NOT NULL, + CONSTRAINT PKC_ReindexJob PRIMARY KEY CLUSTERED (Id) +); + +CREATE TABLE dbo.ResourceChangeData ( + Id BIGINT IDENTITY (1, 1) NOT NULL, + Timestamp DATETIME2 (7) CONSTRAINT DF_ResourceChangeData_Timestamp DEFAULT sysutcdatetime() NOT NULL, + ResourceId VARCHAR (64) NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceVersion INT NOT NULL, + ResourceChangeTypeId TINYINT NOT NULL +) ON PartitionScheme_ResourceChangeData_Timestamp (Timestamp); + +CREATE CLUSTERED INDEX IXC_ResourceChangeData + ON dbo.ResourceChangeData(Id ASC) WITH (ONLINE = ON) + ON PartitionScheme_ResourceChangeData_Timestamp (Timestamp); + +CREATE TABLE dbo.ResourceChangeDataStaging ( + Id BIGINT IDENTITY (1, 1) NOT NULL, + Timestamp DATETIME2 (7) CONSTRAINT DF_ResourceChangeDataStaging_Timestamp DEFAULT sysutcdatetime() NOT NULL, + ResourceId VARCHAR (64) NOT NULL, + ResourceTypeId SMALLINT NOT NULL, + ResourceVersion INT NOT NULL, + ResourceChangeTypeId TINYINT NOT NULL +) ON [PRIMARY]; + +CREATE CLUSTERED INDEX IXC_ResourceChangeDataStaging + ON dbo.ResourceChangeDataStaging(Id ASC, Timestamp ASC) WITH (ONLINE = ON) + ON [PRIMARY]; + +ALTER TABLE dbo.ResourceChangeDataStaging WITH CHECK + ADD CONSTRAINT CHK_ResourceChangeDataStaging_partition CHECK (Timestamp < CONVERT (DATETIME2 (7), N'9999-12-31 23:59:59.9999999')); + +ALTER TABLE dbo.ResourceChangeDataStaging CHECK CONSTRAINT CHK_ResourceChangeDataStaging_partition; + +CREATE TABLE dbo.ResourceChangeType ( + ResourceChangeTypeId TINYINT NOT NULL, + Name NVARCHAR (50) NOT NULL, + CONSTRAINT PK_ResourceChangeType PRIMARY KEY CLUSTERED (ResourceChangeTypeId), + CONSTRAINT UQ_ResourceChangeType_Name UNIQUE NONCLUSTERED (Name) +) ON [PRIMARY]; + + +GO +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (0, N'Creation'); + +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (1, N'Update'); + +INSERT dbo.ResourceChangeType (ResourceChangeTypeId, Name) +VALUES (2, N'Deletion'); + +CREATE TABLE dbo.ResourceType ( + ResourceTypeId SMALLINT IDENTITY (1, 1) NOT NULL, + Name NVARCHAR (50) COLLATE Latin1_General_100_CS_AS NOT NULL, + CONSTRAINT UQ_ResourceType_ResourceTypeId UNIQUE (ResourceTypeId), + CONSTRAINT PKC_ResourceType PRIMARY KEY CLUSTERED (Name) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.ResourceWriteClaim ( + ResourceSurrogateId BIGINT NOT NULL, + ClaimTypeId TINYINT NOT NULL, + ClaimValue NVARCHAR (128) NOT NULL +) +WITH (DATA_COMPRESSION = PAGE); + +CREATE CLUSTERED INDEX IXC_ResourceWriteClaim + ON dbo.ResourceWriteClaim(ResourceSurrogateId, ClaimTypeId); + +CREATE TABLE dbo.CurrentResource ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + IsHistory BIT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NOT NULL, + IsRawResourceMetaSet BIT NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL +); + + +GO +DROP TABLE dbo.CurrentResource; + + +GO +CREATE TABLE dbo.Resource ( + ResourceTypeId SMALLINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version INT NOT NULL, + IsHistory BIT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NOT NULL, + IsRawResourceMetaSet BIT DEFAULT 0 NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL CONSTRAINT PKC_Resource PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + CONSTRAINT CH_Resource_RawResource_Length CHECK (RawResource > 0x0) +); + +ALTER TABLE dbo.Resource SET (LOCK_ESCALATION = AUTO); + +CREATE INDEX IX_ResourceTypeId_TransactionId + ON dbo.Resource(ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_ResourceTypeId_HistoryTransactionId + ON dbo.Resource(ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId_Version + ON dbo.Resource(ResourceTypeId, ResourceId, Version) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId + ON dbo.Resource(ResourceTypeId, ResourceId) + INCLUDE(Version, IsDeleted) WHERE IsHistory = 0 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId + ON dbo.Resource(ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 + AND IsDeleted = 0 + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.SchemaMigrationProgress ( + Timestamp DATETIME2 (3) DEFAULT CURRENT_TIMESTAMP, + Message NVARCHAR (MAX) +); + +CREATE TABLE dbo.SearchParam ( + SearchParamId SMALLINT IDENTITY (1, 1) NOT NULL, + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Status VARCHAR (20) NULL, + LastUpdated DATETIMEOFFSET (7) NULL, + IsPartiallySupported BIT NULL, + CONSTRAINT UQ_SearchParam_SearchParamId UNIQUE (SearchParamId), + CONSTRAINT PKC_SearchParam PRIMARY KEY CLUSTERED (Uri) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE dbo.StringSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (256) COLLATE Latin1_General_100_CI_AI_SC NOT NULL, + TextOverflow NVARCHAR (MAX) COLLATE Latin1_General_100_CI_AI_SC NULL, + IsMin BIT CONSTRAINT string_IsMin_Constraint DEFAULT 0 NOT NULL, + IsMax BIT CONSTRAINT string_IsMax_Constraint DEFAULT 0 NOT NULL +); + +ALTER TABLE dbo.StringSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_StringSearchParam + ON dbo.StringSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Text_INCLUDE_TextOverflow_IsMin_IsMax + ON dbo.StringSearchParam(SearchParamId, Text) + INCLUDE(TextOverflow, IsMin, IsMax) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Text_INCLUDE_IsMin_IsMax_WHERE_TextOverflow_NOT_NULL + ON dbo.StringSearchParam(SearchParamId, Text) + INCLUDE(IsMin, IsMax) WHERE TextOverflow IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.System ( + SystemId INT IDENTITY (1, 1) NOT NULL, + Value NVARCHAR (256) NOT NULL, + CONSTRAINT UQ_System_SystemId UNIQUE (SystemId), + CONSTRAINT PKC_System PRIMARY KEY CLUSTERED (Value) WITH (DATA_COMPRESSION = PAGE) +); + +CREATE TABLE [dbo].[TaskInfo] ( + [TaskId] VARCHAR (64) NOT NULL, + [QueueId] VARCHAR (64) NOT NULL, + [Status] SMALLINT NOT NULL, + [TaskTypeId] SMALLINT NOT NULL, + [RunId] VARCHAR (50) NULL, + [IsCanceled] BIT NOT NULL, + [RetryCount] SMALLINT NOT NULL, + [MaxRetryCount] SMALLINT NOT NULL, + [HeartbeatDateTime] DATETIME2 (7) NULL, + [InputData] VARCHAR (MAX) NOT NULL, + [TaskContext] VARCHAR (MAX) NULL, + [Result] VARCHAR (MAX) NULL, + [CreateDateTime] DATETIME2 (7) CONSTRAINT DF_TaskInfo_CreateDate DEFAULT SYSUTCDATETIME() NOT NULL, + [StartDateTime] DATETIME2 (7) NULL, + [EndDateTime] DATETIME2 (7) NULL, + [Worker] VARCHAR (100) NULL, + [RestartInfo] VARCHAR (MAX) NULL, + [ParentTaskId] VARCHAR (64) NULL, + CONSTRAINT PKC_TaskInfo PRIMARY KEY CLUSTERED (TaskId) WITH (DATA_COMPRESSION = PAGE) +) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; + + +GO +CREATE NONCLUSTERED INDEX IX_QueueId_Status + ON dbo.TaskInfo(QueueId, Status); + + +GO +CREATE NONCLUSTERED INDEX IX_QueueId_ParentTaskId + ON dbo.TaskInfo(QueueId, ParentTaskId); + +CREATE TABLE dbo.TokenDateTimeCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + StartDateTime2 DATETIME2 (7) NOT NULL, + EndDateTime2 DATETIME2 (7) NOT NULL, + IsLongerThanADay2 BIT NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenDateTimeCompositeSearchParam + ADD CONSTRAINT CHK_TokenDateTimeCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenDateTimeCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenDateTimeCompositeSearchParam + ON dbo.TokenDateTimeCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_StartDateTime2_EndDateTime2_INCLUDE_SystemId1_IsLongerThanADay2 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, StartDateTime2, EndDateTime2) + INCLUDE(SystemId1, IsLongerThanADay2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_EndDateTime2_StartDateTime2_INCLUDE_SystemId1_IsLongerThanADay2 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, EndDateTime2, StartDateTime2) + INCLUDE(SystemId1, IsLongerThanADay2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_StartDateTime2_EndDateTime2_INCLUDE_SystemId1_WHERE_IsLongerThanADay2_1 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, StartDateTime2, EndDateTime2) + INCLUDE(SystemId1) WHERE IsLongerThanADay2 = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_EndDateTime2_StartDateTime2_INCLUDE_SystemId1_WHERE_IsLongerThanADay2_1 + ON dbo.TokenDateTimeCompositeSearchParam(SearchParamId, Code1, EndDateTime2, StartDateTime2) + INCLUDE(SystemId1) WHERE IsLongerThanADay2 = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenNumberNumberCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + SingleValue3 DECIMAL (36, 18) NULL, + LowValue3 DECIMAL (36, 18) NULL, + HighValue3 DECIMAL (36, 18) NULL, + HasRange BIT NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenNumberNumberCompositeSearchParam + ADD CONSTRAINT CHK_TokenNumberNumberCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenNumberNumberCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenNumberNumberCompositeSearchParam + ON dbo.TokenNumberNumberCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_SingleValue2_SingleValue3_INCLUDE_SystemId1_WHERE_HasRange_0 + ON dbo.TokenNumberNumberCompositeSearchParam(SearchParamId, Code1, SingleValue2, SingleValue3) + INCLUDE(SystemId1) WHERE HasRange = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_LowValue2_HighValue2_LowValue3_HighValue3_INCLUDE_SystemId1_WHERE_HasRange_1 + ON dbo.TokenNumberNumberCompositeSearchParam(SearchParamId, Code1, LowValue2, HighValue2, LowValue3, HighValue3) + INCLUDE(SystemId1) WHERE HasRange = 1 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenQuantityCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SystemId2 INT NULL, + QuantityCodeId2 INT NULL, + SingleValue2 DECIMAL (36, 18) NULL, + LowValue2 DECIMAL (36, 18) NULL, + HighValue2 DECIMAL (36, 18) NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenQuantityCompositeSearchParam + ADD CONSTRAINT CHK_TokenQuantityCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenQuantityCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenQuantityCompositeSearchParam + ON dbo.TokenQuantityCompositeSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_SingleValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_SingleValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, SingleValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE SingleValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_LowValue2_HighValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_LowValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, LowValue2, HighValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE LowValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_HighValue2_LowValue2_INCLUDE_QuantityCodeId2_SystemId1_SystemId2_WHERE_LowValue2_NOT_NULL + ON dbo.TokenQuantityCompositeSearchParam(SearchParamId, Code1, HighValue2, LowValue2) + INCLUDE(QuantityCodeId2, SystemId1, SystemId2) WHERE LowValue2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId INT NULL, + Code VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenSearchParam + ADD CONSTRAINT CHK_TokenSearchParam_CodeOverflow CHECK (LEN(Code) = 256 + OR CodeOverflow IS NULL); + +ALTER TABLE dbo.TokenSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenSearchParam + ON dbo.TokenSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code_INCLUDE_SystemId + ON dbo.TokenSearchParam(SearchParamId, Code) + INCLUDE(SystemId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenStringCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + Text2 NVARCHAR (256) COLLATE Latin1_General_CI_AI NOT NULL, + TextOverflow2 NVARCHAR (MAX) COLLATE Latin1_General_CI_AI NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenStringCompositeSearchParam + ADD CONSTRAINT CHK_TokenStringCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenStringCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenStringCompositeSearchParam + ON dbo.TokenStringCompositeSearchParam(ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Text2_INCLUDE_SystemId1_TextOverflow2 + ON dbo.TokenStringCompositeSearchParam(SearchParamId, Code1, Text2) + INCLUDE(SystemId1, TextOverflow2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Text2_INCLUDE_SystemId1_WHERE_TextOverflow2_NOT_NULL + ON dbo.TokenStringCompositeSearchParam(SearchParamId, Code1, Text2) + INCLUDE(SystemId1) WHERE TextOverflow2 IS NOT NULL WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenText ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Text NVARCHAR (400) COLLATE Latin1_General_CI_AI NOT NULL, + IsHistory BIT NOT NULL +); + +ALTER TABLE dbo.TokenText + ADD CONSTRAINT DF_TokenText_IsHistory DEFAULT 0 FOR IsHistory; + +ALTER TABLE dbo.TokenText SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenText + ON dbo.TokenText(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE NONCLUSTERED INDEX IX_TokenText_SearchParamId_Text + ON dbo.TokenText(ResourceTypeId, SearchParamId, Text, ResourceSurrogateId) WHERE IsHistory = 0 WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.TokenTokenCompositeSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + SystemId1 INT NULL, + Code1 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + SystemId2 INT NULL, + Code2 VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL, + CodeOverflow1 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL, + CodeOverflow2 VARCHAR (MAX) COLLATE Latin1_General_100_CS_AS NULL +); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam + ADD CONSTRAINT CHK_TokenTokenCompositeSearchParam_CodeOverflow1 CHECK (LEN(Code1) = 256 + OR CodeOverflow1 IS NULL); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam + ADD CONSTRAINT CHK_TokenTokenCompositeSearchParam_CodeOverflow2 CHECK (LEN(Code2) = 256 + OR CodeOverflow2 IS NULL); + +ALTER TABLE dbo.TokenTokenCompositeSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_TokenTokenCompositeSearchParam + ON dbo.TokenTokenCompositeSearchParam(ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Code1_Code2_INCLUDE_SystemId1_SystemId2 + ON dbo.TokenTokenCompositeSearchParam(SearchParamId, Code1, Code2) + INCLUDE(SystemId1, SystemId2) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.Transactions ( + SurrogateIdRangeFirstValue BIGINT NOT NULL, + SurrogateIdRangeLastValue BIGINT NOT NULL, + Definition VARCHAR (2000) NULL, + IsCompleted BIT CONSTRAINT DF_Transactions_IsCompleted DEFAULT 0 NOT NULL, + IsSuccess BIT CONSTRAINT DF_Transactions_IsSuccess DEFAULT 0 NOT NULL, + IsVisible BIT CONSTRAINT DF_Transactions_IsVisible DEFAULT 0 NOT NULL, + IsHistoryMoved BIT CONSTRAINT DF_Transactions_IsHistoryMoved DEFAULT 0 NOT NULL, + CreateDate DATETIME CONSTRAINT DF_Transactions_CreateDate DEFAULT getUTCdate() NOT NULL, + EndDate DATETIME NULL, + VisibleDate DATETIME NULL, + HistoryMovedDate DATETIME NULL, + HeartbeatDate DATETIME CONSTRAINT DF_Transactions_HeartbeatDate DEFAULT getUTCdate() NOT NULL, + FailureReason VARCHAR (MAX) NULL, + IsControlledByClient BIT CONSTRAINT DF_Transactions_IsControlledByClient DEFAULT 1 NOT NULL, + InvisibleHistoryRemovedDate DATETIME NULL CONSTRAINT PKC_Transactions_SurrogateIdRangeFirstValue PRIMARY KEY CLUSTERED (SurrogateIdRangeFirstValue) +); + +CREATE INDEX IX_IsVisible + ON dbo.Transactions(IsVisible); + +CREATE TABLE dbo.UriSearchParam ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + SearchParamId SMALLINT NOT NULL, + Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL +); + +ALTER TABLE dbo.UriSearchParam SET (LOCK_ESCALATION = AUTO); + +CREATE CLUSTERED INDEX IXC_UriSearchParam + ON dbo.UriSearchParam(ResourceTypeId, ResourceSurrogateId, SearchParamId) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE INDEX IX_SearchParamId_Uri + ON dbo.UriSearchParam(SearchParamId, Uri) WITH (DATA_COMPRESSION = PAGE) + ON PartitionScheme_ResourceTypeId (ResourceTypeId); + +CREATE TABLE dbo.WatchdogLeases ( + Watchdog VARCHAR (100) NOT NULL, + LeaseHolder VARCHAR (100) CONSTRAINT DF_WatchdogLeases_LeaseHolder DEFAULT '' NOT NULL, + LeaseEndTime DATETIME CONSTRAINT DF_WatchdogLeases_LeaseEndTime DEFAULT 0 NOT NULL, + RemainingLeaseTimeSec AS datediff(second, getUTCdate(), LeaseEndTime), + LeaseRequestor VARCHAR (100) CONSTRAINT DF_WatchdogLeases_LeaseRequestor DEFAULT '' NOT NULL, + LeaseRequestTime DATETIME CONSTRAINT DF_WatchdogLeases_LeaseRequestTime DEFAULT 0 NOT NULL CONSTRAINT PKC_WatchdogLeases_Watchdog PRIMARY KEY CLUSTERED (Watchdog) +); + +COMMIT +GO +CREATE PROCEDURE dbo.AcquireReindexJobs +@jobHeartbeatTimeoutThresholdInSeconds BIGINT, @maximumNumberOfConcurrentJobsAllowed INT +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; +BEGIN TRANSACTION; +DECLARE @expirationDateTime AS DATETIME2 (7); +SELECT @expirationDateTime = DATEADD(second, -@jobHeartbeatTimeoutThresholdInSeconds, SYSUTCDATETIME()); +DECLARE @numberOfRunningJobs AS INT; +SELECT @numberOfRunningJobs = COUNT(*) +FROM dbo.ReindexJob WITH (TABLOCKX) +WHERE Status = 'Running' + AND HeartbeatDateTime > @expirationDateTime; +DECLARE @limit AS INT = @maximumNumberOfConcurrentJobsAllowed - @numberOfRunningJobs; +IF (@limit > 0) + BEGIN + DECLARE @availableJobs TABLE ( + Id VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + JobVersion BINARY (8) NOT NULL); + INSERT INTO @availableJobs + SELECT TOP (@limit) Id, + JobVersion + FROM dbo.ReindexJob + WHERE (Status = 'Queued' + OR (Status = 'Running' + AND HeartbeatDateTime <= @expirationDateTime)) + ORDER BY HeartbeatDateTime; + DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); + UPDATE dbo.ReindexJob + SET Status = 'Running', + HeartbeatDateTime = @heartbeatDateTime, + RawJobRecord = JSON_MODIFY(RawJobRecord, '$.status', 'Running') + OUTPUT inserted.RawJobRecord, inserted.JobVersion + FROM dbo.ReindexJob AS job + INNER JOIN + @availableJobs AS availableJob + ON job.Id = availableJob.Id + AND job.JobVersion = availableJob.JobVersion; + END +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.AcquireWatchdogLease +@Watchdog VARCHAR (100), @Worker VARCHAR (100), @AllowRebalance BIT=1, @ForceAcquire BIT=0, @LeasePeriodSec FLOAT, @WorkerIsRunning BIT=0, @LeaseEndTime DATETIME OUTPUT, @IsAcquired BIT OUTPUT, @CurrentLeaseHolder VARCHAR (100)=NULL OUTPUT +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +DECLARE @SP AS VARCHAR (100) = 'AcquireWatchdogLease', @Mode AS VARCHAR (100), @msg AS VARCHAR (1000), @MyLeasesNumber AS INT, @OtherValidRequestsOrLeasesNumber AS INT, @MyValidRequestsOrLeasesNumber AS INT, @DesiredLeasesNumber AS INT, @NotLeasedWatchdogNumber AS INT, @WatchdogNumber AS INT, @Now AS DATETIME, @MyLastChangeTime AS DATETIME, @PreviousLeaseHolder AS VARCHAR (100), @Rows AS INT = 0, @NumberOfWorkers AS INT, @st AS DATETIME = getUTCdate(), @RowsInt AS INT, @Pattern AS VARCHAR (100); +BEGIN TRY + SET @Mode = 'R=' + isnull(@Watchdog, 'NULL') + ' W=' + isnull(@Worker, 'NULL') + ' F=' + isnull(CONVERT (VARCHAR, @ForceAcquire), 'NULL') + ' LP=' + isnull(CONVERT (VARCHAR, @LeasePeriodSec), 'NULL'); + SET @CurrentLeaseHolder = ''; + SET @IsAcquired = 0; + SET @Now = getUTCdate(); + SET @LeaseEndTime = @Now; + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderIncludePatternFor' + @Watchdog), ''); + IF @Pattern IS NULL + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderIncludePattern'), ''); + IF @Pattern IS NOT NULL + AND @Worker NOT LIKE @Pattern + BEGIN + SET @msg = 'Worker does not match include pattern=' + @Pattern; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; + SET @CurrentLeaseHolder = isnull((SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog), ''); + RETURN; + END + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderExcludePatternFor' + @Watchdog), ''); + IF @Pattern IS NULL + SET @Pattern = NULLIF ((SELECT Char + FROM dbo.Parameters + WHERE Id = 'WatchdogLeaseHolderExcludePattern'), ''); + IF @Pattern IS NOT NULL + AND @Worker LIKE @Pattern + BEGIN + SET @msg = 'Worker matches exclude pattern=' + @Pattern; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; + SET @CurrentLeaseHolder = isnull((SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog), ''); + RETURN; + END + DECLARE @Watchdogs TABLE ( + Watchdog VARCHAR (100) PRIMARY KEY); + INSERT INTO @Watchdogs + SELECT Watchdog + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE RemainingLeaseTimeSec * (-1) > 10 * @LeasePeriodSec + OR @ForceAcquire = 1 + AND Watchdog = @Watchdog + AND LeaseHolder <> @Worker; + IF @@rowcount > 0 + BEGIN + DELETE dbo.WatchdogLeases + WHERE Watchdog IN (SELECT Watchdog + FROM @Watchdogs); + SET @Rows += @@rowcount; + IF @Rows > 0 + BEGIN + SET @msg = ''; + SELECT @msg = CONVERT (VARCHAR (1000), @msg + CASE WHEN @msg = '' THEN '' ELSE ',' END + Watchdog) + FROM @Watchdogs; + SET @msg = CONVERT (VARCHAR (1000), 'Remove old/forced leases:' + @msg); + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Target = 'WatchdogLeases', @Action = 'Delete', @Rows = @Rows, @Text = @msg; + END + END + SET @NumberOfWorkers = 1 + (SELECT count(*) + FROM (SELECT LeaseHolder + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder <> @Worker + UNION + SELECT LeaseRequestor + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseRequestor <> @Worker + AND LeaseRequestor <> '') AS A); + SET @Mode = CONVERT (VARCHAR (100), @Mode + ' N=' + CONVERT (VARCHAR (10), @NumberOfWorkers)); + IF NOT EXISTS (SELECT * + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE Watchdog = @Watchdog) + INSERT INTO dbo.WatchdogLeases (Watchdog, LeaseEndTime, LeaseRequestTime) + SELECT @Watchdog, + dateadd(day, -10, @Now), + dateadd(day, -10, @Now) + WHERE NOT EXISTS (SELECT * + FROM dbo.WatchdogLeases WITH (TABLOCKX) + WHERE Watchdog = @Watchdog); + SET @LeaseEndTime = dateadd(second, @LeasePeriodSec, @Now); + SET @WatchdogNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK)); + SET @NotLeasedWatchdogNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = '' + OR LeaseEndTime < @Now); + SET @MyLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = @Worker + AND LeaseEndTime > @Now); + SET @OtherValidRequestsOrLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder <> @Worker + AND LeaseEndTime > @Now + OR LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec); + SET @MyValidRequestsOrLeasesNumber = (SELECT count(*) + FROM dbo.WatchdogLeases WITH (NOLOCK) + WHERE LeaseHolder = @Worker + AND LeaseEndTime > @Now + OR LeaseRequestor = @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec); + SET @DesiredLeasesNumber = ceiling(1.0 * @WatchdogNumber / @NumberOfWorkers); + IF @DesiredLeasesNumber = 0 + SET @DesiredLeasesNumber = 1; + IF @DesiredLeasesNumber = 1 + AND @OtherValidRequestsOrLeasesNumber = 1 + AND @WatchdogNumber = 1 + SET @DesiredLeasesNumber = 0; + IF @MyValidRequestsOrLeasesNumber = floor(1.0 * @WatchdogNumber / @NumberOfWorkers) + AND @OtherValidRequestsOrLeasesNumber + @MyValidRequestsOrLeasesNumber = @WatchdogNumber + SET @DesiredLeasesNumber = @DesiredLeasesNumber - 1; + UPDATE dbo.WatchdogLeases + SET LeaseHolder = @Worker, + LeaseEndTime = @LeaseEndTime, + LeaseRequestor = '', + @PreviousLeaseHolder = LeaseHolder + WHERE Watchdog = @Watchdog + AND NOT (LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec) + AND (LeaseHolder = @Worker + AND (LeaseEndTime > @Now + OR @WorkerIsRunning = 1) + OR LeaseEndTime < @Now + AND (@DesiredLeasesNumber > @MyLeasesNumber + OR @OtherValidRequestsOrLeasesNumber < @WatchdogNumber)); + IF @@rowcount > 0 + BEGIN + SET @IsAcquired = 1; + SET @msg = 'Lease holder changed from [' + isnull(@PreviousLeaseHolder, '') + '] to [' + @Worker + ']'; + IF @PreviousLeaseHolder <> @Worker + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Text = @msg; + END + ELSE + IF @AllowRebalance = 1 + BEGIN + SET @CurrentLeaseHolder = (SELECT LeaseHolder + FROM dbo.WatchdogLeases + WHERE Watchdog = @Watchdog); + UPDATE dbo.WatchdogLeases + SET LeaseRequestTime = @Now + WHERE Watchdog = @Watchdog + AND LeaseRequestor = @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec; + IF @DesiredLeasesNumber > @MyValidRequestsOrLeasesNumber + BEGIN + UPDATE A + SET LeaseRequestor = @Worker, + LeaseRequestTime = @Now + FROM dbo.WatchdogLeases AS A + WHERE Watchdog = @Watchdog + AND NOT (LeaseRequestor <> @Worker + AND datediff(second, LeaseRequestTime, @Now) < @LeasePeriodSec) + AND @NotLeasedWatchdogNumber = 0 + AND (SELECT count(*) + FROM dbo.WatchdogLeases AS B + WHERE B.LeaseHolder = A.LeaseHolder + AND datediff(second, B.LeaseEndTime, @Now) < @LeasePeriodSec) > @DesiredLeasesNumber; + SET @RowsInt = @@rowcount; + SET @msg = '@DesiredLeasesNumber=[' + CONVERT (VARCHAR (10), @DesiredLeasesNumber) + '] > @MyValidRequestsOrLeasesNumber=[' + CONVERT (VARCHAR (10), @MyValidRequestsOrLeasesNumber) + ']'; + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Info', @Mode = @Mode, @Rows = @RowsInt, @Text = @msg; + END + END + SET @Mode = CONVERT (VARCHAR (100), @Mode + ' A=' + CONVERT (VARCHAR (1), @IsAcquired)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = 'AcquireWatchdogLease', @Status = 'Error', @Mode = @Mode; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.AddPartitionOnResourceChanges +@partitionBoundary DATETIME2 (7) OUTPUT +AS +BEGIN + SET XACT_ABORT ON; + BEGIN TRANSACTION; + DECLARE @rightPartitionBoundary AS DATETIME2 (7) = CAST ((SELECT TOP (1) value + FROM sys.partition_range_values AS prv + INNER JOIN + sys.partition_functions AS pf + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + ORDER BY prv.boundary_id DESC) AS DATETIME2 (7)); + DECLARE @timestamp AS DATETIME2 (7) = DATEADD(hour, DATEDIFF(hour, 0, sysutcdatetime()), 0); + IF (@rightPartitionBoundary < @timestamp) + BEGIN + SET @rightPartitionBoundary = @timestamp; + END + SET @rightPartitionBoundary = DATEADD(hour, 1, @rightPartitionBoundary); + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [Primary]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@rightPartitionBoundary); + SET @partitionBoundary = @rightPartitionBoundary; + COMMIT TRANSACTION; +END + +GO +CREATE PROCEDURE dbo.ArchiveJobs +@QueueType TINYINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'ArchiveJobs', @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0, @InflightRows AS INT = 0, @Lock AS VARCHAR (100) = 'DequeueJob_' + CONVERT (VARCHAR, @QueueType); +BEGIN TRY + SET @PartitionId = @MaxPartitions * rand(); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + WHILE @LookedAtPartitions <= @MaxPartitions + BEGIN + SET @InflightRows += (SELECT count(*) + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (0, 1)); + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + IF @InflightRows = 0 + BEGIN + SET @LookedAtPartitions = 0; + WHILE @LookedAtPartitions <= @MaxPartitions + BEGIN + UPDATE dbo.JobQueue + SET Status = 5 + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (2, 3, 4); + SET @Rows += @@rowcount; + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.CaptureResourceChanges +@isDeleted BIT, @version INT, @resourceId VARCHAR (64), @resourceTypeId SMALLINT +AS +BEGIN + DECLARE @changeType AS SMALLINT; + IF (@isDeleted = 1) + BEGIN + SET @changeType = 2; + END + ELSE + BEGIN + IF (@version = 1) + BEGIN + SET @changeType = 0; + END + ELSE + BEGIN + SET @changeType = 1; + END + END + INSERT INTO dbo.ResourceChangeData (ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId) + VALUES (@resourceId, @resourceTypeId, @version, @changeType); +END + +GO +CREATE PROCEDURE dbo.CaptureResourceIdsForChanges +@Resources dbo.ResourceList READONLY +AS +SET NOCOUNT ON; +INSERT INTO dbo.ResourceChangeData (ResourceId, ResourceTypeId, ResourceVersion, ResourceChangeTypeId) +SELECT ResourceId, + ResourceTypeId, + Version, + CASE WHEN IsDeleted = 1 THEN 2 WHEN Version > 1 THEN 1 ELSE 0 END +FROM @Resources +WHERE IsHistory = 0; + +GO +CREATE PROCEDURE dbo.CheckActiveReindexJobs +AS +SET NOCOUNT ON; +SELECT Id +FROM dbo.ReindexJob +WHERE Status = 'Running' + OR Status = 'Queued' + OR Status = 'Paused'; + +GO +CREATE PROCEDURE dbo.CleanupEventLog +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'CleanupEventLog', @Mode AS VARCHAR (100) = '', @MaxDeleteRows AS INT, @MaxAllowedRows AS BIGINT, @RetentionPeriodSecond AS INT, @DeletedRows AS INT, @TotalDeletedRows AS INT = 0, @TotalRows AS INT, @Now AS DATETIME = getUTCdate(); +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; +BEGIN TRY + SET @MaxDeleteRows = (SELECT Number + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.DeleteBatchSize'); + IF @MaxDeleteRows IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.DeleteBatchSize', 18, 127); + SET @MaxAllowedRows = (SELECT Number + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.AllowedRows'); + IF @MaxAllowedRows IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.AllowedRows', 18, 127); + SET @RetentionPeriodSecond = (SELECT Number * 24 * 60 * 60 + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.RetentionPeriodDay'); + IF @RetentionPeriodSecond IS NULL + RAISERROR ('Cannot get Parameter.CleanupEventLog.RetentionPeriodDay', 18, 127); + SET @TotalRows = (SELECT sum(row_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id('EventLog') + AND index_id IN (0, 1)); + SET @DeletedRows = 1; + WHILE @DeletedRows > 0 + AND EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'CleanupEventLog.IsEnabled' + AND Number = 1) + BEGIN + SET @DeletedRows = 0; + IF @TotalRows - @TotalDeletedRows > @MaxAllowedRows + BEGIN + DELETE TOP (@MaxDeleteRows) + dbo.EventLog WITH (PAGLOCK) + WHERE EventDate <= dateadd(second, -@RetentionPeriodSecond, @Now); + SET @DeletedRows = @@rowcount; + SET @TotalDeletedRows += @DeletedRows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'EventLog', @Action = 'Delete', @Rows = @DeletedRows, @Text = @TotalDeletedRows; + END + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @Now; +END TRY +BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.ConfigurePartitionOnResourceChanges +@numberOfFuturePartitionsToAdd INT +AS +BEGIN + SET XACT_ABORT ON; + BEGIN TRANSACTION; + DECLARE @partitionBoundary AS DATETIME2 (7) = DATEADD(hour, DATEDIFF(hour, 0, sysutcdatetime()), 0); + DECLARE @startingRightPartitionBoundary AS DATETIME2 (7) = CAST ((SELECT TOP (1) value + FROM sys.partition_range_values AS prv + INNER JOIN + sys.partition_functions AS pf + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + ORDER BY prv.boundary_id DESC) AS DATETIME2 (7)); + DECLARE @numberOfPartitionsToAdd AS INT = @numberOfFuturePartitionsToAdd + 1; + WHILE @numberOfPartitionsToAdd > 0 + BEGIN + IF (@startingRightPartitionBoundary < @partitionBoundary) + BEGIN + ALTER PARTITION SCHEME PartitionScheme_ResourceChangeData_Timestamp NEXT USED [PRIMARY]; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + SPLIT RANGE (@partitionBoundary); + END + SET @partitionBoundary = DATEADD(hour, 1, @partitionBoundary); + SET @numberOfPartitionsToAdd -= 1; + END + COMMIT TRANSACTION; +END + +GO +CREATE PROCEDURE dbo.CreateReindexJob +@id VARCHAR (64), @status VARCHAR (10), @rawJobRecord VARCHAR (MAX) +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +BEGIN TRANSACTION; +DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); +INSERT INTO dbo.ReindexJob (Id, Status, HeartbeatDateTime, RawJobRecord) +VALUES (@id, @status, @heartbeatDateTime, @rawJobRecord); +SELECT CAST (MIN_ACTIVE_ROWVERSION() AS INT); +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.CreateResourceSearchParamStats +@Table VARCHAR (100), @Column VARCHAR (100), @ResourceTypeId SMALLINT, @SearchParamId SMALLINT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'T=' + isnull(@Table, 'NULL') + ' C=' + isnull(@Column, 'NULL') + ' RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' SP=' + isnull(CONVERT (VARCHAR, @SearchParamId), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + IF @Table IS NULL + OR @Column IS NULL + OR @ResourceTypeId IS NULL + OR @SearchParamId IS NULL + RAISERROR ('@TableName IS NULL OR @KeyColumn IS NULL OR @ResourceTypeId IS NULL OR @SearchParamId IS NULL', 18, 127); + EXECUTE ('CREATE STATISTICS ST_' + @Column + '_WHERE_ResourceTypeId_' + @ResourceTypeId + '_SearchParamId_' + @SearchParamId + ' ON dbo.' + @Table + ' (' + @Column + ') WHERE ResourceTypeId = ' + @ResourceTypeId + ' AND SearchParamId = ' + @SearchParamId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = 'Stats created'; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF error_number() = 1927 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; + RETURN; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.Defrag +@TableName VARCHAR (100), @IndexName VARCHAR (200), @PartitionNumber INT, @IsPartitioned BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = @TableName + '.' + @IndexName + '.' + CONVERT (VARCHAR, @PartitionNumber) + '.' + CONVERT (VARCHAR, @IsPartitioned), @st AS DATETIME = getUTCdate(), @SQL AS VARCHAR (3500), @msg AS VARCHAR (1000), @SizeBefore AS FLOAT, @SizeAfter AS FLOAT, @IndexId AS INT, @Operation AS VARCHAR (50) = CASE WHEN EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'Defrag.IndexRebuild.IsEnabled' + AND Number = 1) THEN 'REBUILD' ELSE 'REORGANIZE' END; +SET @Mode = @Mode + ' ' + @Operation; +BEGIN TRY + SET @IndexId = (SELECT index_id + FROM sys.indexes + WHERE object_id = object_id(@TableName) + AND name = @IndexName); + SET @Sql = 'ALTER INDEX ' + quotename(@IndexName) + ' ON dbo.' + quotename(@TableName) + ' ' + @Operation + CASE WHEN @IsPartitioned = 1 THEN ' PARTITION = ' + CONVERT (VARCHAR, @PartitionNumber) ELSE '' END + CASE WHEN @Operation = 'REBUILD' THEN ' WITH (ONLINE = ON' + CASE WHEN EXISTS (SELECT * + FROM sys.partitions + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId + AND data_compression_desc = 'PAGE') THEN ', DATA_COMPRESSION = PAGE' ELSE '' END + ')' ELSE '' END; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start', @Text = @Sql; + SET @SizeBefore = (SELECT sum(reserved_page_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId + AND partition_number = @PartitionNumber) * 8.0 / 1024 / 1024; + SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Text = @msg; + BEGIN TRY + EXECUTE (@Sql); + SET @SizeAfter = (SELECT sum(reserved_page_count) + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@TableName) + AND index_id = @IndexId + AND partition_number = @PartitionNumber) * 8.0 / 1024 / 1024; + SET @msg = 'Size[GB] before=' + CONVERT (VARCHAR, @SizeBefore) + ', after=' + CONVERT (VARCHAR, @SizeAfter) + ', reduced by=' + CONVERT (VARCHAR, @SizeBefore - @SizeAfter); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'End', @Mode = @Mode, @Action = @Operation, @Start = @st, @Text = @msg; + END TRY + BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Error', @Mode = @Mode, @Action = @Operation, @Start = @st; + THROW; + END CATCH +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DefragChangeDatabaseSettings +@IsOn BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DefragChangeDatabaseSettings', @Mode AS VARCHAR (200) = 'On=' + CONVERT (VARCHAR, @IsOn), @st AS DATETIME = getUTCdate(), @SQL AS VARCHAR (3500); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Start', @Mode = @Mode; + SET @SQL = 'ALTER DATABASE CURRENT SET AUTO_UPDATE_STATISTICS ' + CASE WHEN @IsOn = 1 THEN 'ON' ELSE 'OFF' END; + EXECUTE (@SQL); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'Run', @Mode = @Mode, @Text = @SQL; + SET @SQL = 'ALTER DATABASE CURRENT SET AUTO_CREATE_STATISTICS ' + CASE WHEN @IsOn = 1 THEN 'ON' ELSE 'OFF' END; + EXECUTE (@SQL); + EXECUTE dbo.LogEvent @Process = @SP, @Status = 'End', @Mode = @Mode, @Start = @st, @Text = @SQL; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DefragGetFragmentation +@TableName VARCHAR (200), @IndexName VARCHAR (200)=NULL, @PartitionNumber INT=NULL +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @st AS DATETIME = getUTCdate(), @msg AS VARCHAR (1000), @Rows AS INT, @MinFragPct AS INT = isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'Defrag.MinFragPct'), 10), @MinSizeGB AS FLOAT = isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'Defrag.MinSizeGB'), 0.1), @PreviousGroupId AS BIGINT, @IndexId AS INT; +DECLARE @Mode AS VARCHAR (200) = 'T=' + @TableName + ' I=' + isnull(@IndexName, 'NULL') + ' P=' + isnull(CONVERT (VARCHAR, @PartitionNumber), 'NULL') + ' MF=' + CONVERT (VARCHAR, @MinFragPct) + ' MS=' + CONVERT (VARCHAR, @MinSizeGB); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF object_id(@TableName) IS NULL + RAISERROR ('Table does not exist', 18, 127); + SET @IndexId = (SELECT index_id + FROM sys.indexes + WHERE object_id = object_id(@TableName) + AND name = @IndexName); + IF @IndexName IS NOT NULL + AND @IndexId IS NULL + RAISERROR ('Index does not exist', 18, 127); + SET @PreviousGroupId = (SELECT TOP 1 GroupId + FROM dbo.JobQueue + WHERE QueueType = 3 + AND Status = 5 + AND Definition = @TableName + ORDER BY GroupId DESC); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@PreviousGroupId', @Text = @PreviousGroupId; + SELECT TableName, + IndexName, + partition_number, + frag_in_percent + FROM (SELECT @TableName AS TableName, + I.name AS IndexName, + partition_number, + avg_fragmentation_in_percent AS frag_in_percent, + isnull(CONVERT (FLOAT, Result), 0) AS prev_frag_in_percent + FROM (SELECT object_id, + index_id, + partition_number, + avg_fragmentation_in_percent + FROM sys.dm_db_index_physical_stats(db_id(), object_id(@TableName), @IndexId, @PartitionNumber, 'LIMITED') AS A + WHERE index_id > 0 + AND (@PartitionNumber IS NOT NULL + OR avg_fragmentation_in_percent >= @MinFragPct + AND A.page_count > @MinSizeGB * 1024 * 1024 / 8)) AS A + INNER JOIN + sys.indexes AS I + ON I.object_id = A.object_id + AND I.index_id = A.index_id + LEFT OUTER JOIN + dbo.JobQueue + ON QueueType = 3 + AND Status = 5 + AND GroupId = @PreviousGroupId + AND Definition = I.name + ';' + CONVERT (VARCHAR, partition_number)) AS A + WHERE @PartitionNumber IS NOT NULL + OR frag_in_percent >= prev_frag_in_percent + @MinFragPct; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DeleteHistory +@DeleteResources BIT=0, @Reset BIT=0, @DisableLogEvent BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DeleteHistory', @Mode AS VARCHAR (100) = 'D=' + isnull(CONVERT (VARCHAR, @DeleteResources), 'NULL') + ' R=' + isnull(CONVERT (VARCHAR, @Reset), 'NULL'), @st AS DATETIME = getUTCdate(), @Id AS VARCHAR (100) = 'DeleteHistory.LastProcessed.TypeId.SurrogateId', @ResourceTypeId AS SMALLINT, @SurrogateId AS BIGINT, @RowsToProcess AS INT, @ProcessedResources AS INT = 0, @DeletedResources AS INT = 0, @DeletedSearchParams AS INT = 0, @ReportDate AS DATETIME = getUTCdate(); +BEGIN TRY + IF @DisableLogEvent = 0 + INSERT INTO dbo.Parameters (Id, Char) + SELECT @SP, + 'LogEvent'; + ELSE + DELETE dbo.Parameters + WHERE Id = @SP; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + INSERT INTO dbo.Parameters (Id, Char) + SELECT @Id, + '0.0' + WHERE NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = @Id); + DECLARE @LastProcessed AS VARCHAR (100) = CASE WHEN @Reset = 0 THEN (SELECT Char + FROM dbo.Parameters + WHERE Id = @Id) ELSE '0.0' END; + DECLARE @Types TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + DECLARE @SurrogateIds TABLE ( + ResourceSurrogateId BIGINT PRIMARY KEY, + IsHistory BIT ); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Insert', @Rows = @@rowcount; + SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1); + SET @SurrogateId = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255); + DELETE @Types + WHERE ResourceTypeId < @ResourceTypeId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Delete', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @Types + ORDER BY ResourceTypeId); + SET @ProcessedResources = 0; + SET @DeletedResources = 0; + SET @DeletedSearchParams = 0; + SET @RowsToProcess = 1; + WHILE @RowsToProcess > 0 + BEGIN + DELETE @SurrogateIds; + INSERT INTO @SurrogateIds + SELECT TOP 10000 ResourceSurrogateId, + IsHistory + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId + ORDER BY ResourceSurrogateId; + SET @RowsToProcess = @@rowcount; + SET @ProcessedResources += @RowsToProcess; + IF @RowsToProcess > 0 + SET @SurrogateId = (SELECT max(ResourceSurrogateId) + FROM @SurrogateIds); + SET @LastProcessed = CONVERT (VARCHAR, @ResourceTypeId) + '.' + CONVERT (VARCHAR, @SurrogateId); + DELETE @SurrogateIds + WHERE IsHistory = 0; + IF EXISTS (SELECT * + FROM @SurrogateIds) + BEGIN + DELETE dbo.ResourceWriteClaim + WHERE ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.CompartmentAssignment + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.ReferenceSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenText + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.StringSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.UriSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.NumberSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.QuantitySearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.DateTimeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.ReferenceTokenCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenTokenCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenDateTimeCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenQuantityCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenStringCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + DELETE dbo.TokenNumberNumberCompositeSearchParam + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedSearchParams += @@rowcount; + IF @DeleteResources = 1 + BEGIN + DELETE dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId IN (SELECT ResourceSurrogateId + FROM @SurrogateIds); + SET @DeletedResources += @@rowcount; + END + END + UPDATE dbo.Parameters + SET Char = @LastProcessed + WHERE Id = @Id; + IF datediff(second, @ReportDate, getUTCdate()) > 60 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Select', @Rows = @ProcessedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '*SearchParam', @Action = 'Delete', @Rows = @DeletedSearchParams, @Text = @LastProcessed; + IF @DeleteResources = 1 + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Rows = @DeletedResources, @Text = @LastProcessed; + SET @ReportDate = getUTCdate(); + SET @ProcessedResources = 0; + SET @DeletedSearchParams = 0; + SET @DeletedResources = 0; + END + END + DELETE @Types + WHERE ResourceTypeId = @ResourceTypeId; + SET @SurrogateId = 0; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Select', @Rows = @ProcessedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '*SearchParam', @Action = 'Delete', @Rows = @DeletedSearchParams, @Text = @LastProcessed; + IF @DeleteResources = 1 + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'Resource', @Action = 'Delete', @Rows = @DeletedResources, @Text = @LastProcessed; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DequeueJob +@QueueType TINYINT, @Worker VARCHAR (100), @HeartbeatTimeoutSec INT, @InputJobId BIGINT=NULL, @CheckTimeoutJobs BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DequeueJob', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' H=' + isnull(CONVERT (VARCHAR, @HeartbeatTimeoutSec), 'NULL') + ' W=' + isnull(@Worker, 'NULL') + ' IJ=' + isnull(CONVERT (VARCHAR, @InputJobId), 'NULL') + ' T=' + isnull(CONVERT (VARCHAR, @CheckTimeoutJobs), 'NULL'), @Rows AS INT = 0, @st AS DATETIME = getUTCdate(), @JobId AS BIGINT, @msg AS VARCHAR (100), @Lock AS VARCHAR (100), @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0; +BEGIN TRY + IF EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'DequeueJobStop' + AND Number = 1) + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = 0, @Text = 'Skipped'; + RETURN; + END + IF @InputJobId IS NULL + SET @PartitionId = @MaxPartitions * rand(); + ELSE + SET @PartitionId = @InputJobId % 16; + SET TRANSACTION ISOLATION LEVEL READ COMMITTED; + WHILE @InputJobId IS NULL + AND @JobId IS NULL + AND @LookedAtPartitions < @MaxPartitions + AND @CheckTimeoutJobs = 0 + BEGIN + SET @Lock = 'DequeueJob_' + CONVERT (VARCHAR, @QueueType) + '_' + CONVERT (VARCHAR, @PartitionId); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + UPDATE T + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = T.JobId + FROM dbo.JobQueue AS T WITH (PAGLOCK) + INNER JOIN + (SELECT TOP 1 JobId + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_PartitionId_Status_Priority)) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 0 + ORDER BY Priority, JobId) AS S + ON QueueType = @QueueType + AND PartitionId = @PartitionId + AND T.JobId = S.JobId; + SET @Rows += @@rowcount; + COMMIT TRANSACTION; + IF @JobId IS NULL + BEGIN + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + SET @LookedAtPartitions = 0; + WHILE @InputJobId IS NULL + AND @JobId IS NULL + AND @LookedAtPartitions < @MaxPartitions + BEGIN + SET @Lock = 'DequeueStoreCopyWorkUnit_' + CONVERT (VARCHAR, @PartitionId); + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + UPDATE T + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = CASE WHEN CancelRequested = 0 THEN 1 ELSE 4 END, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = CASE WHEN CancelRequested = 0 THEN T.JobId END, + Info = CONVERT (VARCHAR (1000), isnull(Info, '') + ' Prev: Worker=' + Worker + ' Start=' + CONVERT (VARCHAR, StartDate, 121)) + FROM dbo.JobQueue AS T WITH (PAGLOCK) + INNER JOIN + (SELECT TOP 1 JobId + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_PartitionId_Status_Priority)) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 1 + AND datediff(second, HeartbeatDate, getUTCdate()) > @HeartbeatTimeoutSec + ORDER BY Priority, JobId) AS S + ON QueueType = @QueueType + AND PartitionId = @PartitionId + AND T.JobId = S.JobId; + SET @Rows += @@rowcount; + COMMIT TRANSACTION; + IF @JobId IS NULL + BEGIN + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions = @LookedAtPartitions + 1; + END + END + IF @InputJobId IS NOT NULL + BEGIN + UPDATE dbo.JobQueue WITH (PAGLOCK) + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = JobId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 0 + AND JobId = @InputJobId; + SET @Rows += @@rowcount; + IF @JobId IS NULL + BEGIN + UPDATE dbo.JobQueue WITH (PAGLOCK) + SET StartDate = getUTCdate(), + HeartbeatDate = getUTCdate(), + Worker = @Worker, + Status = 1, + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()), + @JobId = JobId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND Status = 1 + AND JobId = @InputJobId + AND datediff(second, HeartbeatDate, getUTCdate()) > @HeartbeatTimeoutSec; + SET @Rows += @@rowcount; + END + END + IF @JobId IS NOT NULL + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobId = @JobId; + SET @msg = 'J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL') + ' P=' + CONVERT (VARCHAR, @PartitionId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Text = @msg; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.DisableIndex +@tableName NVARCHAR (128), @indexName NVARCHAR (128) +WITH EXECUTE AS 'dbo' +AS +DECLARE @errorTxt AS VARCHAR (1000), @sql AS NVARCHAR (1000), @isDisabled AS BIT; +IF object_id(@tableName) IS NULL + BEGIN + SET @errorTxt = @tableName + ' does not exist or you don''t have permissions.'; + RAISERROR (@errorTxt, 18, 127); + END +SET @isDisabled = (SELECT is_disabled + FROM sys.indexes + WHERE object_id = object_id(@tableName) + AND name = @indexName); +IF @isDisabled IS NULL + BEGIN + SET @errorTxt = @indexName + ' does not exist or you don''t have permissions.'; + RAISERROR (@errorTxt, 18, 127); + END +IF @isDisabled = 0 + BEGIN + SET @sql = N'ALTER INDEX ' + QUOTENAME(@indexName) + N' on ' + @tableName + ' Disable'; + EXECUTE sp_executesql @sql; + END + +GO +CREATE PROCEDURE dbo.DisableIndexes +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'DisableIndexes', @Mode AS VARCHAR (200) = '', @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100), @Ind AS VARCHAR (200), @Txt AS VARCHAR (4000); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + Tbl VARCHAR (100) PRIMARY KEY, + Supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + DECLARE @Indexes TABLE ( + Tbl VARCHAR (100), + Ind VARCHAR (200), + TblId INT , + IndId INT PRIMARY KEY (Tbl, Ind)); + INSERT INTO @Indexes + SELECT Tbl, + I.Name, + TblId, + I.index_id + FROM (SELECT object_id(Tbl) AS TblId, + Tbl + FROM @Tables) AS O + INNER JOIN + sys.indexes AS I + ON I.object_id = TblId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + INSERT INTO dbo.IndexProperties (TableName, IndexName, PropertyName, PropertyValue) + SELECT Tbl, + Ind, + 'DATA_COMPRESSION', + data_comp + FROM (SELECT Tbl, + Ind, + isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions + WHERE object_id = TblId + AND index_id = IndId), 'NONE') AS data_comp + FROM @Indexes) AS A + WHERE NOT EXISTS (SELECT * + FROM dbo.IndexProperties + WHERE TableName = Tbl + AND IndexName = Ind); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'IndexProperties', @Action = 'Insert', @Rows = @@rowcount; + DELETE @Indexes + WHERE Tbl = 'Resource' + OR IndId = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Delete', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @Tbl = Tbl, + @Ind = Ind + FROM @Indexes; + SET @Txt = 'ALTER INDEX ' + @Ind + ' ON dbo.' + @Tbl + ' DISABLE'; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Ind, @Action = 'Disable', @Text = @Txt; + DELETE @Indexes + WHERE Tbl = @Tbl + AND Ind = @Ind; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.EnqueueJobs +@QueueType TINYINT, @Definitions StringList READONLY, @GroupId BIGINT=NULL, @ForceOneActiveJobGroup BIT=1, @IsCompleted BIT=NULL, @Status TINYINT=NULL, @Result VARCHAR (MAX)=NULL, @StartDate DATETIME=NULL, @ReturnJobs BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'EnqueueJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' D=' + CONVERT (VARCHAR, (SELECT count(*) + FROM @Definitions)) + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL') + ' F=' + isnull(CONVERT (VARCHAR, @ForceOneActiveJobGroup), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @Status), 'NULL'), @st AS DATETIME = getUTCdate(), @Lock AS VARCHAR (100) = 'EnqueueJobs_' + CONVERT (VARCHAR, @QueueType), @MaxJobId AS BIGINT, @Rows AS INT, @msg AS VARCHAR (1000), @JobIds AS BigintList, @InputRows AS INT; +BEGIN TRY + DECLARE @Input TABLE ( + DefinitionHash VARBINARY (20) PRIMARY KEY, + Definition VARCHAR (MAX) ); + INSERT INTO @Input + SELECT hashbytes('SHA1', String) AS DefinitionHash, + String AS Definition + FROM @Definitions; + SET @InputRows = @@rowcount; + INSERT INTO @JobIds + SELECT JobId + FROM @Input AS A + INNER JOIN + dbo.JobQueue AS B + ON B.QueueType = @QueueType + AND B.DefinitionHash = A.DefinitionHash + AND B.Status <> 5; + IF @@rowcount < @InputRows + BEGIN + BEGIN TRANSACTION; + EXECUTE sp_getapplock @Lock, 'Exclusive'; + IF @ForceOneActiveJobGroup = 1 + AND EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND Status IN (0, 1) + AND (@GroupId IS NULL + OR GroupId <> @GroupId)) + RAISERROR ('There are other active job groups', 18, 127); + SET @MaxJobId = isnull((SELECT TOP 1 JobId + FROM dbo.JobQueue + WHERE QueueType = @QueueType + ORDER BY JobId DESC), 0); + INSERT INTO dbo.JobQueue (QueueType, GroupId, JobId, Definition, DefinitionHash, Status, Result, StartDate, EndDate) + OUTPUT inserted.JobId INTO @JobIds + SELECT @QueueType, + isnull(@GroupId, @MaxJobId + 1) AS GroupId, + JobId, + Definition, + DefinitionHash, + isnull(@Status, 0) AS Status, + CASE WHEN @Status = 2 THEN @Result ELSE NULL END AS Result, + CASE WHEN @Status = 1 THEN getUTCdate() ELSE @StartDate END AS StartDate, + CASE WHEN @Status = 2 THEN getUTCdate() ELSE NULL END AS EndDate + FROM (SELECT @MaxJobId + row_number() OVER (ORDER BY Dummy) AS JobId, + * + FROM (SELECT *, + 0 AS Dummy + FROM @Input) AS A) AS A + WHERE NOT EXISTS (SELECT * + FROM dbo.JobQueue AS B WITH (INDEX (IX_QueueType_DefinitionHash)) + WHERE B.QueueType = @QueueType + AND B.DefinitionHash = A.DefinitionHash + AND B.Status <> 5); + SET @Rows = @@rowcount; + COMMIT TRANSACTION; + END + IF @ReturnJobs = 1 + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.ExecuteCommandForRebuildIndexes +@Tbl VARCHAR (100), @Ind VARCHAR (1000), @Cmd VARCHAR (MAX) +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'ExecuteCommandForRebuildIndexes', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL'), @st AS DATETIME, @Retries AS INT = 0, @Action AS VARCHAR (100), @msg AS VARCHAR (1000); +RetryOnTempdbError: +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start', @Text = @Cmd; + SET @st = getUTCdate(); + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + IF @Cmd IS NULL + RAISERROR ('@Cmd IS NULL', 18, 127); + SET @Action = CASE WHEN @Cmd LIKE 'UPDATE STAT%' THEN 'Update statistics' WHEN @Cmd LIKE 'CREATE%INDEX%' THEN 'Create Index' WHEN @Cmd LIKE 'ALTER%INDEX%REBUILD%' THEN 'Rebuild Index' WHEN @Cmd LIKE 'ALTER%TABLE%ADD%' THEN 'Add Constraint' END; + IF @Action IS NULL + BEGIN + SET @msg = 'Not supported command = ' + CONVERT (VARCHAR (900), @Cmd); + RAISERROR (@msg, 18, 127); + END + IF @Action = 'Create Index' + WAITFOR DELAY '00:00:05'; + EXECUTE (@Cmd); + SELECT @Ind; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Action = @Action, @Status = 'End', @Start = @st, @Text = @Cmd; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF error_number() = 40544 + BEGIN + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st, @Retry = @Retries; + SET @Retries = @Retries + 1; + IF @Tbl = 'TokenText_96' + WAITFOR DELAY '01:00:00'; + ELSE + WAITFOR DELAY '00:10:00'; + GOTO RetryOnTempdbError; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.FetchEventAgentCheckpoint +@CheckpointId VARCHAR (64) +AS +BEGIN + SELECT TOP (1) CheckpointId, + LastProcessedDateTime, + LastProcessedIdentifier + FROM dbo.EventAgentCheckpoint + WHERE CheckpointId = @CheckpointId; +END + +GO +CREATE PROCEDURE dbo.FetchResourceChanges_3 +@startId BIGINT, @lastProcessedUtcDateTime DATETIME2 (7), @pageSize SMALLINT +AS +BEGIN + SET NOCOUNT ON; + DECLARE @precedingPartitionBoundary AS DATETIME2 (7) = (SELECT TOP (1) CAST (prv.value AS DATETIME2 (7)) AS value + FROM sys.partition_range_values AS prv WITH (NOLOCK) + INNER JOIN + sys.partition_functions AS pf WITH (NOLOCK) + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + AND SQL_VARIANT_PROPERTY(prv.Value, 'BaseType') = 'datetime2' + AND CAST (prv.value AS DATETIME2 (7)) < DATEADD(HOUR, DATEDIFF(HOUR, 0, @lastProcessedUtcDateTime), 0) + ORDER BY prv.boundary_id DESC); + IF (@precedingPartitionBoundary IS NULL) + BEGIN + SET @precedingPartitionBoundary = CONVERT (DATETIME2 (7), N'1970-01-01T00:00:00.0000000'); + END + DECLARE @endDateTimeToFilter AS DATETIME2 (7) = DATEADD(HOUR, 1, SYSUTCDATETIME()); + WITH PartitionBoundaries + AS (SELECT CAST (prv.value AS DATETIME2 (7)) AS PartitionBoundary + FROM sys.partition_range_values AS prv WITH (NOLOCK) + INNER JOIN + sys.partition_functions AS pf WITH (NOLOCK) + ON pf.function_id = prv.function_id + WHERE pf.name = N'PartitionFunction_ResourceChangeData_Timestamp' + AND SQL_VARIANT_PROPERTY(prv.Value, 'BaseType') = 'datetime2' + AND CAST (prv.value AS DATETIME2 (7)) BETWEEN @precedingPartitionBoundary AND @endDateTimeToFilter) + SELECT TOP (@pageSize) Id, + Timestamp, + ResourceId, + ResourceTypeId, + ResourceVersion, + ResourceChangeTypeId + FROM PartitionBoundaries AS p CROSS APPLY (SELECT TOP (@pageSize) Id, + Timestamp, + ResourceId, + ResourceTypeId, + ResourceVersion, + ResourceChangeTypeId + FROM dbo.ResourceChangeData WITH (TABLOCK, HOLDLOCK) + WHERE Id >= @startId + AND $PARTITION.PartitionFunction_ResourceChangeData_Timestamp (Timestamp) = $PARTITION.PartitionFunction_ResourceChangeData_Timestamp (p.PartitionBoundary) + ORDER BY Id ASC) AS rcd + ORDER BY rcd.Id ASC; +END + +GO +CREATE PROCEDURE dbo.GetActiveJobs +@QueueType TINYINT, @GroupId BIGINT=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetActiveJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL'), @st AS DATETIME = getUTCdate(), @JobIds AS BigintList, @PartitionId AS TINYINT, @MaxPartitions AS TINYINT = 16, @LookedAtPartitions AS TINYINT = 0, @Rows AS INT = 0; +BEGIN TRY + SET @PartitionId = @MaxPartitions * rand(); + WHILE @LookedAtPartitions < @MaxPartitions + BEGIN + IF @GroupId IS NULL + INSERT INTO @JobIds + SELECT JobId + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND Status IN (0, 1); + ELSE + INSERT INTO @JobIds + SELECT JobId + FROM dbo.JobQueue + WHERE PartitionId = @PartitionId + AND QueueType = @QueueType + AND GroupId = @GroupId + AND Status IN (0, 1); + SET @Rows += @@rowcount; + SET @PartitionId = CASE WHEN @PartitionId = 15 THEN 0 ELSE @PartitionId + 1 END; + SET @LookedAtPartitions += 1; + END + IF @Rows > 0 + EXECUTE dbo.GetJobs @QueueType = @QueueType, @JobIds = @JobIds; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetCommandsForRebuildIndexes +@RebuildClustered BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetCommandsForRebuildIndexes', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId RC=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100), @TblInt AS VARCHAR (100), @Ind AS VARCHAR (200), @IndId AS INT, @Supported AS BIT, @Txt AS VARCHAR (MAX), @Rows AS BIGINT, @Pages AS BIGINT, @ResourceTypeId AS SMALLINT, @IndexesCnt AS INT, @DataComp AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Commands TABLE ( + Tbl VARCHAR (100), + Ind VARCHAR (200), + Txt VARCHAR (MAX), + Pages BIGINT ); + DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY); + DECLARE @Indexes TABLE ( + Ind VARCHAR (200) PRIMARY KEY, + IndId INT ); + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + Supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SELECT TOP 1 @Tbl = name, + @Supported = Supported + FROM @Tables + ORDER BY name; + IF @Supported = 0 + BEGIN + INSERT INTO @Commands + SELECT @Tbl, + name, + 'ALTER INDEX ' + name + ' ON dbo.' + @Tbl + ' REBUILD' + CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = name) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END, + CONVERT (BIGINT, 9e18) + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (is_disabled = 1 + AND index_id > 1 + AND @RebuildClustered = 0 + OR index_id = 1 + AND @RebuildClustered = 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Commands', @Action = 'Insert', @Rows = @@rowcount, @Text = 'Not supported tables with disabled indexes'; + END + ELSE + BEGIN + DELETE @ResourceTypes; + INSERT INTO @ResourceTypes + SELECT CONVERT (SMALLINT, substring(name, charindex('_', name) + 1, 6)) AS ResourceTypeId + FROM sys.sysobjects + WHERE name LIKE @Tbl + '[_]%'; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@ResourceTypes', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @ResourceTypes + ORDER BY ResourceTypeId); + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + SET @Pages = (SELECT dpages + FROM sysindexes + WHERE id = object_id(@TblInt) + AND indid IN (0, 1)); + DELETE @Indexes; + INSERT INTO @Indexes + SELECT name, + index_id + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (index_id > 1 + AND @RebuildClustered = 0 + OR index_id = 1 + AND @RebuildClustered = 1); + SET @IndexesCnt = 0; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @Ind = Ind, + @IndId = IndId + FROM @Indexes + ORDER BY Ind; + IF @IndId = 1 + BEGIN + SET @Txt = 'ALTER INDEX ' + @Ind + ' ON dbo.' + @TblInt + ' REBUILD' + CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = @Ind) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END; + INSERT INTO @Commands + SELECT @TblInt, + @Ind, + @Txt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = @Txt; + END + ELSE + IF NOT EXISTS (SELECT * + FROM sys.indexes + WHERE object_id = object_id(@TblInt) + AND name = @Ind) + BEGIN + EXECUTE dbo.GetIndexCommands @Tbl = @Tbl, @Ind = @Ind, @AddPartClause = 0, @IncludeClustered = 0, @Txt = @Txt OUTPUT; + SET @Txt = replace(@Txt, '[' + @Tbl + ']', @TblInt); + IF @Txt IS NOT NULL + BEGIN + SET @IndexesCnt = @IndexesCnt + 1; + INSERT INTO @Commands + SELECT @TblInt, + @Ind, + @Txt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = @Txt; + END + END + DELETE @Indexes + WHERE Ind = @Ind; + END + IF @IndexesCnt > 1 + BEGIN + INSERT INTO @Commands + SELECT @TblInt, + 'UPDATE STAT', + 'UPDATE STATISTICS dbo.' + @TblInt, + @Pages; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Add command', @Rows = @@rowcount, @Text = 'Add stats update'; + END + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + END + DELETE @Tables + WHERE name = @Tbl; + END + SELECT Tbl, + Ind, + Txt + FROM @Commands + ORDER BY Pages DESC, Tbl, CASE WHEN Txt LIKE 'UPDATE STAT%' THEN 0 ELSE 1 END; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Commands', @Action = 'Select', @Rows = @@rowcount; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetIndexCommands +@Tbl VARCHAR (100), @Ind VARCHAR (200), @AddPartClause BIT, @IncludeClustered BIT, @Txt VARCHAR (MAX)=NULL OUTPUT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetIndexCommands', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL') + ' Ind=' + isnull(@Ind, 'NULL'), @st AS DATETIME = getUTCdate(); +DECLARE @Indexes TABLE ( + Ind VARCHAR (200) PRIMARY KEY, + Txt VARCHAR (MAX)); +BEGIN TRY + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT Ind, + CASE WHEN is_primary_key = 1 THEN 'ALTER TABLE dbo.[' + Tbl + '] ADD PRIMARY KEY ' + CASE WHEN type = 1 THEN ' CLUSTERED' ELSE '' END ELSE 'CREATE' + CASE WHEN is_unique = 1 THEN ' UNIQUE' ELSE '' END + CASE WHEN type = 1 THEN ' CLUSTERED' ELSE '' END + ' INDEX ' + Ind + ' ON dbo.[' + Tbl + ']' END + ' (' + KeyCols + ')' + IncClause + CASE WHEN filter_def IS NOT NULL THEN ' WHERE ' + filter_def ELSE '' END + CASE WHEN data_comp IS NOT NULL THEN ' WITH (DATA_COMPRESSION = ' + data_comp + ')' ELSE '' END + CASE WHEN @AddPartClause = 1 THEN PartClause ELSE '' END + FROM (SELECT O.Name AS Tbl, + I.Name AS Ind, + isnull((SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions AS P + WHERE P.object_id = I.object_id + AND I.index_id = P.index_id), (SELECT NULLIF (PropertyValue, 'NONE') + FROM dbo.IndexProperties + WHERE TableName = O.Name + AND IndexName = I.Name + AND PropertyName = 'DATA_COMPRESSION')) AS data_comp, + replace(replace(replace(replace(I.filter_definition, '[', ''), ']', ''), '(', ''), ')', '') AS filter_def, + I.is_unique, + I.is_primary_key, + I.type, + KeyCols, + CASE WHEN IncCols IS NOT NULL THEN ' INCLUDE (' + IncCols + ')' ELSE '' END AS IncClause, + CASE WHEN EXISTS (SELECT * + FROM sys.partition_schemes AS S + WHERE S.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') THEN ' ON PartitionScheme_ResourceTypeId (ResourceTypeId)' ELSE '' END AS PartClause + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id CROSS APPLY (SELECT string_agg(CASE WHEN IC.key_ordinal > 0 + AND IC.is_included_column = 0 THEN C.name END, ',') WITHIN GROUP (ORDER BY key_ordinal) AS KeyCols, + string_agg(CASE WHEN IC.is_included_column = 1 THEN C.name END, ',') WITHIN GROUP (ORDER BY key_ordinal) AS IncCols + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = IC.object_id + AND C.column_id = IC.column_id + WHERE IC.object_id = I.object_id + AND IC.index_id = I.index_id + GROUP BY IC.object_id, IC.index_id) AS IC + WHERE O.name = @Tbl + AND (@Ind IS NULL + OR I.name = @Ind) + AND (@IncludeClustered = 1 + OR index_id > 1)) AS A; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + IF @Ind IS NULL + SELECT Ind, + Txt + FROM @Indexes; + ELSE + SET @Txt = (SELECT Txt + FROM @Indexes); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Text = @Txt; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetJobs +@QueueType TINYINT, @JobId BIGINT=NULL, @JobIds BigintList READONLY, @GroupId BIGINT=NULL, @ReturnDefinition BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetJobs', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL'), @st AS DATETIME = getUTCdate(), @PartitionId AS TINYINT = @JobId % 16; +BEGIN TRY + IF @JobId IS NULL + AND @GroupId IS NULL + AND NOT EXISTS (SELECT * + FROM @JobIds) + RAISERROR ('@JobId = NULL and @GroupId = NULL and @JobIds is empty', 18, 127); + IF @JobId IS NOT NULL + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = isnull(@JobId, -1) + AND Status <> 5; + ELSE + IF @GroupId IS NOT NULL + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue WITH (INDEX (IX_QueueType_GroupId)) + WHERE QueueType = @QueueType + AND GroupId = isnull(@GroupId, -1) + AND Status <> 5; + ELSE + SELECT GroupId, + JobId, + CASE WHEN @ReturnDefinition = 1 THEN Definition ELSE NULL END AS Definition, + Version, + Status, + Priority, + Data, + Result, + CreateDate, + StartDate, + EndDate, + HeartbeatDate, + CancelRequested + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND JobId IN (SELECT Id + FROM @JobIds) + AND PartitionId = JobId % 16 + AND Status <> 5; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetPartitionedTables +@IncludeNotDisabled BIT=1, @IncludeNotSupported BIT=1 +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetPartitionedTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId D=' + isnull(CONVERT (VARCHAR, @IncludeNotDisabled), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @IncludeNotSupported), 'NULL'), @st AS DATETIME = getUTCdate(); +DECLARE @NotSupportedTables TABLE ( + id INT PRIMARY KEY); +BEGIN TRY + INSERT INTO @NotSupportedTables + SELECT DISTINCT O.object_id + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') + AND (NOT EXISTS (SELECT * + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = IC.object_id + AND C.column_id = IC.column_id + WHERE IC.object_id = I.object_id + AND IC.index_id = I.index_id + AND IC.key_ordinal > 0 + AND IC.is_included_column = 0 + AND C.name = 'ResourceTypeId') + OR EXISTS (SELECT * + FROM sys.indexes AS NSI + WHERE NSI.object_id = O.object_id + AND NOT EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = NSI.data_space_id + AND name = 'PartitionScheme_ResourceTypeId'))); + SELECT CONVERT (VARCHAR (100), O.name), + CONVERT (BIT, CASE WHEN EXISTS (SELECT * + FROM @NotSupportedTables AS NSI + WHERE NSI.id = O.object_id) THEN 0 ELSE 1 END) + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND I.index_id IN (0, 1) + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId') + AND EXISTS (SELECT * + FROM sys.index_columns AS IC + INNER JOIN + sys.columns AS C + ON C.object_id = I.object_id + AND C.column_id = IC.column_id + AND IC.is_included_column = 0 + AND C.name = 'ResourceTypeId') + AND (@IncludeNotSupported = 1 + OR NOT EXISTS (SELECT * + FROM @NotSupportedTables AS NSI + WHERE NSI.id = O.object_id)) + AND (@IncludeNotDisabled = 1 + OR EXISTS (SELECT * + FROM sys.indexes AS D + WHERE D.object_id = O.object_id + AND D.is_disabled = 1)) + ORDER BY 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetReindexJobById +@id VARCHAR (64) +AS +SET NOCOUNT ON; +SELECT RawJobRecord, + JobVersion +FROM dbo.ReindexJob +WHERE Id = @id; + +GO +CREATE PROCEDURE dbo.GetResources +@ResourceKeys dbo.ResourceKeyList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResources', @InputRows AS INT, @DummyTop AS BIGINT = 9223372036854775807, @NotNullVersionExists AS BIT, @NullVersionExists AS BIT, @MinRT AS SMALLINT, @MaxRT AS SMALLINT; +SELECT @MinRT = min(ResourceTypeId), + @MaxRT = max(ResourceTypeId), + @InputRows = count(*), + @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), + @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) +FROM @ResourceKeys; +DECLARE @Mode AS VARCHAR (100) = 'RT=[' + CONVERT (VARCHAR, @MinRT) + ',' + CONVERT (VARCHAR, @MaxRT) + '] Cnt=' + CONVERT (VARCHAR, @InputRows) + ' NNVE=' + CONVERT (VARCHAR, @NotNullVersionExists) + ' NVE=' + CONVERT (VARCHAR, @NullVersionExists); +BEGIN TRY + IF @NotNullVersionExists = 1 + IF @NullVersionExists = 0 + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys) AS A + INNER JOIN + dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys + WHERE Version IS NOT NULL) AS A + INNER JOIN + dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys + WHERE Version IS NULL) AS A + INNER JOIN + dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0) AS A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT B.ResourceTypeId, + B.ResourceId, + ResourceSurrogateId, + B.Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceKeys) AS A + INNER JOIN + dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId)) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourcesByTransactionId +@TransactionId BIGINT, @IncludeHistory BIT=0, @ReturnResourceKeysOnly BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId) + ' H=' + CONVERT (VARCHAR, @IncludeHistory), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807, @TypeId AS SMALLINT; +BEGIN TRY + DECLARE @Types TABLE ( + TypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + DECLARE @Keys TABLE ( + TypeId SMALLINT, + SurrogateId BIGINT PRIMARY KEY (TypeId, SurrogateId)); + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @TypeId = (SELECT TOP 1 TypeId + FROM @Types + ORDER BY TypeId); + INSERT INTO @Keys + SELECT @TypeId, + ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @TypeId + AND TransactionId = @TransactionId; + DELETE @Types + WHERE TypeId = @TypeId; + END + IF @ReturnResourceKeysOnly = 0 + SELECT ResourceTypeId, + ResourceId, + ResourceSurrogateId, + Version, + IsDeleted, + IsHistory, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + RequestMethod + FROM (SELECT TOP (@DummyTop) * + FROM @Keys) AS A + INNER JOIN + dbo.Resource AS B + ON ResourceTypeId = TypeId + AND ResourceSurrogateId = SurrogateId + WHERE IsHistory = 0 + OR @IncludeHistory = 1 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + ELSE + SELECT ResourceTypeId, + ResourceId, + ResourceSurrogateId, + Version, + IsDeleted + FROM (SELECT TOP (@DummyTop) * + FROM @Keys) AS A + INNER JOIN + dbo.Resource AS B + ON ResourceTypeId = TypeId + AND ResourceSurrogateId = SurrogateId + WHERE IsHistory = 0 + OR @IncludeHistory = 1 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange +@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @GlobalEndId BIGINT=NULL, @IncludeHistory BIT=0, @IncludeDeleted BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetResourcesByTypeAndSurrogateIdRange', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' GE=' + isnull(CONVERT (VARCHAR, @GlobalEndId), 'NULL') + ' HI=' + isnull(CONVERT (VARCHAR, @IncludeHistory), 'NULL') + ' DE' + isnull(CONVERT (VARCHAR, @IncludeDeleted), 'NULL'), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807; +BEGIN TRY + DECLARE @ResourceIds TABLE ( + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY); + DECLARE @SurrogateIds TABLE ( + MaxSurrogateId BIGINT PRIMARY KEY); + IF @GlobalEndId IS NOT NULL + AND @IncludeHistory = 0 + BEGIN + INSERT INTO @ResourceIds + SELECT DISTINCT ResourceId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + IF @@rowcount > 0 + INSERT INTO @SurrogateIds + SELECT ResourceSurrogateId + FROM (SELECT ResourceId, + ResourceSurrogateId, + row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) AS RowId + FROM dbo.Resource WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId + FROM @ResourceIds) + AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId) AS A + WHERE RowId = 1 + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + END + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND (IsHistory = 0 + OR @IncludeHistory = 1) + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource + FROM @SurrogateIds + INNER JOIN + dbo.Resource + ON ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceSearchParamStats +@Table VARCHAR (100)=NULL, @ResourceTypeId SMALLINT=NULL, @SearchParamId SMALLINT=NULL +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'T=' + isnull(@Table, 'NULL') + ' RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' SP=' + isnull(CONVERT (VARCHAR, @SearchParamId), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + SELECT T.name AS TableName, + S.name AS StatsName, + db_name() AS DatabaseName + FROM sys.stats AS S + INNER JOIN + sys.tables AS T + ON T.object_id = S.object_id + WHERE T.name LIKE '%SearchParam' + AND T.name <> 'SearchParam' + AND S.name LIKE 'ST[_]%' + AND (T.name LIKE @Table + OR @Table IS NULL) + AND (S.name LIKE '%ResourceTypeId[_]' + CONVERT (VARCHAR, @ResourceTypeId) + '[_]%' + OR @ResourceTypeId IS NULL) + AND (S.name LIKE '%SearchParamId[_]' + CONVERT (VARCHAR, @SearchParamId) + OR @SearchParamId IS NULL); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Rows = @@rowcount, @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceSurrogateIdRanges +@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @RangeSize INT, @NumberOfRanges INT=100, @Up BIT=1 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetResourceSurrogateIdRanges', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' R=' + isnull(CONVERT (VARCHAR, @RangeSize), 'NULL') + ' UP=' + isnull(CONVERT (VARCHAR, @Up), 'NULL'), @st AS DATETIME = getUTCdate(); +BEGIN TRY + IF @Up = 1 + SELECT RangeId, + min(ResourceSurrogateId), + max(ResourceSurrogateId), + count(*) + FROM (SELECT isnull(CONVERT (INT, (row_number() OVER (ORDER BY ResourceSurrogateId) - 1) / @RangeSize), 0) AS RangeId, + ResourceSurrogateId + FROM (SELECT TOP (@RangeSize * @NumberOfRanges) ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId >= @StartId + AND ResourceSurrogateId <= @EndId + ORDER BY ResourceSurrogateId) AS A) AS A + GROUP BY RangeId + OPTION (MAXDOP 1); + ELSE + SELECT RangeId, + min(ResourceSurrogateId), + max(ResourceSurrogateId), + count(*) + FROM (SELECT isnull(CONVERT (INT, (row_number() OVER (ORDER BY ResourceSurrogateId) - 1) / @RangeSize), 0) AS RangeId, + ResourceSurrogateId + FROM (SELECT TOP (@RangeSize * @NumberOfRanges) ResourceSurrogateId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId >= @StartId + AND ResourceSurrogateId <= @EndId + ORDER BY ResourceSurrogateId DESC) AS A) AS A + GROUP BY RangeId + OPTION (MAXDOP 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetResourceVersions +@ResourceDateKeys dbo.ResourceDateKeyList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = 'GetResourceVersions', @Mode AS VARCHAR (100) = 'Rows=' + CONVERT (VARCHAR, (SELECT count(*) + FROM @ResourceDateKeys)), @DummyTop AS BIGINT = 9223372036854775807; +BEGIN TRY + SELECT A.ResourceTypeId, + A.ResourceId, + A.ResourceSurrogateId, + CASE WHEN D.Version IS NOT NULL THEN 0 WHEN isnull(U.Version, 1) - isnull(L.Version, 0) > ResourceIndex THEN isnull(U.Version, 1) - ResourceIndex ELSE isnull(M.Version, 0) - ResourceIndex END AS Version, + isnull(D.Version, 0) AS MatchedVersion, + D.RawResource AS MatchedRawResource + FROM (SELECT TOP (@DummyTop) *, + CONVERT (INT, row_number() OVER (PARTITION BY ResourceTypeId, ResourceId ORDER BY ResourceSurrogateId DESC)) AS ResourceIndex + FROM @ResourceDateKeys) AS A OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version > 0 + AND B.ResourceSurrogateId < A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId DESC) AS L OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version > 0 + AND B.ResourceSurrogateId > A.ResourceSurrogateId + ORDER BY B.ResourceSurrogateId) AS U OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.Version < 0 + ORDER BY B.Version) AS M OUTER APPLY (SELECT TOP 1 * + FROM dbo.Resource AS B WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) AS D + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.GetSearchParamStatuses +AS +SET NOCOUNT ON; +SELECT SearchParamId, + Uri, + Status, + LastUpdated, + IsPartiallySupported +FROM dbo.SearchParam; + +GO +CREATE PROCEDURE dbo.GetTransactions +@StartNotInclusiveTranId BIGINT, @EndInclusiveTranId BIGINT, @EndDate DATETIME=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'ST=' + CONVERT (VARCHAR, @StartNotInclusiveTranId) + ' ET=' + CONVERT (VARCHAR, @EndInclusiveTranId) + ' ED=' + isnull(CONVERT (VARCHAR, @EndDate, 121), 'NULL'), @st AS DATETIME = getUTCdate(); +IF @EndDate IS NULL + SET @EndDate = getUTCdate(); +SELECT SurrogateIdRangeFirstValue, + VisibleDate, + InvisibleHistoryRemovedDate +FROM dbo.Transactions +WHERE SurrogateIdRangeFirstValue > @StartNotInclusiveTranId + AND SurrogateIdRangeFirstValue <= @EndInclusiveTranId + AND EndDate <= @EndDate +ORDER BY SurrogateIdRangeFirstValue; +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; + +GO +CREATE PROCEDURE dbo.GetUsedResourceTypes +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'GetUsedResourceTypes', @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(); +BEGIN TRY + SELECT ResourceTypeId, + Name + FROM dbo.ResourceType AS A + WHERE EXISTS (SELECT * + FROM dbo.Resource AS B + WHERE B.ResourceTypeId = A.ResourceTypeId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.HardDeleteResource +@ResourceTypeId SMALLINT, @ResourceId VARCHAR (64), @KeepCurrentVersion BIT, @IsResourceChangeCaptureEnabled BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = 'RT=' + CONVERT (VARCHAR, @ResourceTypeId) + ' R=' + @ResourceId + ' V=' + CONVERT (VARCHAR, @KeepCurrentVersion) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled), @st AS DATETIME = getUTCdate(), @TransactionId AS BIGINT; +BEGIN TRY + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUTPUT; + IF @KeepCurrentVersion = 0 + BEGIN TRANSACTION; + DECLARE @SurrogateIds TABLE ( + ResourceSurrogateId BIGINT NOT NULL); + IF @IsResourceChangeCaptureEnabled = 1 + AND NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'InvisibleHistory.IsEnabled' + AND Number = 0) + UPDATE dbo.Resource + SET IsDeleted = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1) + AND RawResource <> 0xF; + ELSE + DELETE dbo.Resource + OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId = @ResourceId + AND (@KeepCurrentVersion = 0 + OR IsHistory = 1) + AND RawResource <> 0xF; + IF @KeepCurrentVersion = 0 + BEGIN + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ResourceWriteClaim AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ReferenceSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenText AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.StringSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.UriSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.NumberSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.QuantitySearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.DateTimeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.ReferenceTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenTokenCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenDateTimeCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenQuantityCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenStringCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + DELETE B + FROM @SurrogateIds AS A + INNER LOOP JOIN + dbo.TokenNumberNumberCompositeSearchParam AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + OPTION (MAXDOP 1); + END + IF @@trancount > 0 + COMMIT TRANSACTION; + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.InitializeIndexProperties +AS +SET NOCOUNT ON; +INSERT INTO dbo.IndexProperties (TableName, IndexName, PropertyName, PropertyValue) +SELECT Tbl, + Ind, + 'DATA_COMPRESSION', + isnull(data_comp, 'NONE') +FROM (SELECT O.Name AS Tbl, + I.Name AS Ind, + (SELECT TOP 1 CASE WHEN data_compression_desc = 'PAGE' THEN 'PAGE' END + FROM sys.partitions AS P + WHERE P.object_id = I.object_id + AND I.index_id = P.index_id) AS data_comp + FROM sys.indexes AS I + INNER JOIN + sys.objects AS O + ON O.object_id = I.object_id + WHERE O.type = 'u' + AND EXISTS (SELECT * + FROM sys.partition_schemes AS PS + WHERE PS.data_space_id = I.data_space_id + AND name = 'PartitionScheme_ResourceTypeId')) AS A +WHERE NOT EXISTS (SELECT * + FROM dbo.IndexProperties + WHERE TableName = Tbl + AND IndexName = Ind); + +GO +CREATE PROCEDURE dbo.LogEvent +@Process VARCHAR (100), @Status VARCHAR (10), @Mode VARCHAR (200)=NULL, @Action VARCHAR (20)=NULL, @Target VARCHAR (100)=NULL, @Rows BIGINT=NULL, @Start DATETIME=NULL, @Text NVARCHAR (3500)=NULL, @EventId BIGINT=NULL OUTPUT, @Retry INT=NULL +AS +SET NOCOUNT ON; +DECLARE @ErrorNumber AS INT = error_number(), @ErrorMessage AS VARCHAR (1000) = '', @TranCount AS INT = @@trancount, @DoWork AS BIT = 0, @NumberAdded AS BIT; +IF @ErrorNumber IS NOT NULL + OR @Status IN ('Warn', 'Error') + SET @DoWork = 1; +IF @DoWork = 0 + SET @DoWork = CASE WHEN EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = isnull(@Process, '') + AND Char = 'LogEvent') THEN 1 ELSE 0 END; +IF @DoWork = 0 + RETURN; +IF @ErrorNumber IS NOT NULL + SET @ErrorMessage = CASE WHEN @Retry IS NOT NULL THEN 'Retry ' + CONVERT (VARCHAR, @Retry) + ', ' ELSE '' END + 'Error ' + CONVERT (VARCHAR, error_number()) + ': ' + CONVERT (VARCHAR (1000), error_message()) + ', Level ' + CONVERT (VARCHAR, error_severity()) + ', State ' + CONVERT (VARCHAR, error_state()) + CASE WHEN error_procedure() IS NOT NULL THEN ', Procedure ' + error_procedure() ELSE '' END + ', Line ' + CONVERT (VARCHAR, error_line()); +IF @TranCount > 0 + AND @ErrorNumber IS NOT NULL + ROLLBACK; +IF databasepropertyex(db_name(), 'UpdateAbility') = 'READ_WRITE' + BEGIN + INSERT INTO dbo.EventLog (Process, Status, Mode, Action, Target, Rows, Milliseconds, EventDate, EventText, SPID, HostName) + SELECT @Process, + @Status, + @Mode, + @Action, + @Target, + @Rows, + datediff(millisecond, @Start, getUTCdate()), + getUTCdate() AS EventDate, + CASE WHEN @ErrorNumber IS NULL THEN @Text ELSE @ErrorMessage + CASE WHEN isnull(@Text, '') <> '' THEN '. ' + @Text ELSE '' END END AS Text, + @@SPID, + host_name() AS HostName; + SET @EventId = scope_identity(); + END +IF @TranCount > 0 + AND @ErrorNumber IS NOT NULL + BEGIN TRANSACTION; + +GO +CREATE PROCEDURE dbo.LogSchemaMigrationProgress +@message VARCHAR (MAX) +AS +INSERT INTO dbo.SchemaMigrationProgress (Message) +VALUES (@message); + +GO +CREATE PROCEDURE dbo.MergeResources +@AffectedRows INT=0 OUTPUT, @RaiseExceptionOnConflict BIT=1, @IsResourceChangeCaptureEnabled BIT=0, @TransactionId BIGINT=NULL, @SingleTransaction BIT=1, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParms dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @DummyTop AS BIGINT = 9223372036854775807, @InitialTranCount AS INT = @@trancount, @IsRetry AS BIT = 0; +DECLARE @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) + FROM @Resources), 'Input=Empty'); +SET @Mode += ' E=' + CONVERT (VARCHAR, @RaiseExceptionOnConflict) + ' CC=' + CONVERT (VARCHAR, @IsResourceChangeCaptureEnabled) + ' IT=' + CONVERT (VARCHAR, @InitialTranCount) + ' T=' + isnull(CONVERT (VARCHAR, @TransactionId), 'NULL'); +SET @AffectedRows = 0; +BEGIN TRY + DECLARE @Existing AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)); + DECLARE @ResourceInfos AS TABLE ( + ResourceTypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL, + Version INT NOT NULL, + KeepHistory BIT NOT NULL, + PreviousVersion INT NULL, + PreviousSurrogateId BIGINT NULL PRIMARY KEY (ResourceTypeId, SurrogateId)); + DECLARE @PreviousSurrogateIds AS TABLE ( + TypeId SMALLINT NOT NULL, + SurrogateId BIGINT NOT NULL PRIMARY KEY (TypeId, SurrogateId), + KeepHistory BIT ); + IF @SingleTransaction = 0 + AND isnull((SELECT Number + FROM dbo.Parameters + WHERE Id = 'MergeResources.NoTransaction.IsEnabled'), 0) = 0 + SET @SingleTransaction = 1; + SET @Mode += ' ST=' + CONVERT (VARCHAR, @SingleTransaction); + IF @InitialTranCount = 0 + BEGIN + IF EXISTS (SELECT * + FROM @Resources AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId) + BEGIN + BEGIN TRANSACTION; + INSERT INTO @Existing (ResourceTypeId, SurrogateId) + SELECT B.ResourceTypeId, + B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * + FROM @Resources) AS A + INNER JOIN + dbo.Resource AS B WITH (ROWLOCK, HOLDLOCK) + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0 + AND B.ResourceId = A.ResourceId + AND B.Version = A.Version + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + IF @@rowcount = (SELECT count(*) + FROM @Resources) + SET @IsRetry = 1; + IF @IsRetry = 0 + COMMIT TRANSACTION; + END + END + SET @Mode += ' R=' + CONVERT (VARCHAR, @IsRetry); + IF @SingleTransaction = 1 + AND @@trancount = 0 + BEGIN TRANSACTION; + IF @IsRetry = 0 + BEGIN + INSERT INTO @ResourceInfos (ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId) + SELECT A.ResourceTypeId, + A.ResourceSurrogateId, + A.Version, + A.KeepHistory, + B.Version, + B.ResourceSurrogateId + FROM (SELECT TOP (@DummyTop) * + FROM @Resources + WHERE HasVersionToCompare = 1) AS A + LEFT OUTER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceId = A.ResourceId + AND B.IsHistory = 0 + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + IF @RaiseExceptionOnConflict = 1 + AND EXISTS (SELECT * + FROM @ResourceInfos + WHERE PreviousVersion IS NOT NULL + AND Version <= PreviousVersion) + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + INSERT INTO @PreviousSurrogateIds + SELECT ResourceTypeId, + PreviousSurrogateId, + KeepHistory + FROM @ResourceInfos + WHERE PreviousSurrogateId IS NOT NULL; + IF @@rowcount > 0 + BEGIN + UPDATE dbo.Resource + SET IsHistory = 1 + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 1); + SET @AffectedRows += @@rowcount; + IF @IsResourceChangeCaptureEnabled = 1 + AND NOT EXISTS (SELECT * + FROM dbo.Parameters + WHERE Id = 'InvisibleHistory.IsEnabled' + AND Number = 0) + UPDATE dbo.Resource + SET IsHistory = 1, + RawResource = 0xF, + SearchParamHash = NULL, + HistoryTransactionId = @TransactionId + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 0); + ELSE + DELETE dbo.Resource + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId + AND KeepHistory = 0); + SET @AffectedRows += @@rowcount; + DELETE dbo.ResourceWriteClaim + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.ReferenceSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenText + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.StringSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.UriSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.NumberSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.QuantitySearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.DateTimeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.ReferenceTokenCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenTokenCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenDateTimeCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenQuantityCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenStringCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + DELETE dbo.TokenNumberNumberCompositeSearchParam + WHERE EXISTS (SELECT * + FROM @PreviousSurrogateIds + WHERE TypeId = ResourceTypeId + AND SurrogateId = ResourceSurrogateId); + SET @AffectedRows += @@rowcount; + END + INSERT INTO dbo.Resource (ResourceTypeId, ResourceId, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId) + SELECT ResourceTypeId, + ResourceId, + Version, + IsHistory, + ResourceSurrogateId, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + @TransactionId + FROM @Resources; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM @ResourceWriteClaims; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceId, + ReferenceResourceVersion + FROM @ReferenceSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM @TokenSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM @TokenTexts; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM @StringSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM @UriSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM @NumberSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM @QuantitySearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM @DateTimeSearchParms; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM @TokenTokenCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM @TokenQuantityCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM @TokenStringCompositeSearchParams; + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM @TokenNumberNumberCompositeSearchParams; + SET @AffectedRows += @@rowcount; + END + ELSE + BEGIN + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM (SELECT TOP (@DummyTop) * + FROM @ResourceWriteClaims) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.ResourceWriteClaim AS C + WHERE C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceId, + ReferenceResourceVersion + FROM (SELECT TOP (@DummyTop) * + FROM @ReferenceSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.ReferenceSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM (SELECT TOP (@DummyTop) * + FROM @TokenSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM (SELECT TOP (@DummyTop) * + FROM @TokenTexts) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM (SELECT TOP (@DummyTop) * + FROM @StringSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenText AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM (SELECT TOP (@DummyTop) * + FROM @UriSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.UriSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM (SELECT TOP (@DummyTop) * + FROM @NumberSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.NumberSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM (SELECT TOP (@DummyTop) * + FROM @QuantitySearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.QuantitySearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM (SELECT TOP (@DummyTop) * + FROM @DateTimeSearchParms) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @ReferenceTokenCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.DateTimeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenTokenCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenTokenCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenDateTimeCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenDateTimeCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenQuantityCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenQuantityCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM (SELECT TOP (@DummyTop) * + FROM @TokenStringCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenStringCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM (SELECT TOP (@DummyTop) * + FROM @TokenNumberNumberCompositeSearchParams) AS A + WHERE EXISTS (SELECT * + FROM @Existing AS B + WHERE B.ResourceTypeId = A.ResourceTypeId + AND B.SurrogateId = A.ResourceSurrogateId) + AND NOT EXISTS (SELECT * + FROM dbo.TokenNumberNumberCompositeSearchParam AS C + WHERE C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceSurrogateId = A.ResourceSurrogateId) + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); + SET @AffectedRows += @@rowcount; + END + IF @IsResourceChangeCaptureEnabled = 1 + EXECUTE dbo.CaptureResourceIdsForChanges @Resources; + IF @TransactionId IS NOT NULL + EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId; + IF @InitialTranCount = 0 + AND @@trancount > 0 + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 + AND @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + IF @RaiseExceptionOnConflict = 1 + AND error_number() IN (2601, 2627) + AND error_message() LIKE '%''dbo.Resource''%' + THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + ELSE + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesAdvanceTransactionVisibility +@AffectedRows INT=0 OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(), @msg AS VARCHAR (1000), @MaxTransactionId AS BIGINT, @MinTransactionId AS BIGINT, @MinNotCompletedTransactionId AS BIGINT, @CurrentTransactionId AS BIGINT; +SET @AffectedRows = 0; +BEGIN TRY + EXECUTE dbo.MergeResourcesGetTransactionVisibility @MinTransactionId OUTPUT; + SET @MinTransactionId += 1; + SET @CurrentTransactionId = (SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + ORDER BY SurrogateIdRangeFirstValue DESC); + SET @MinNotCompletedTransactionId = isnull((SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsCompleted = 0 + AND SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + ORDER BY SurrogateIdRangeFirstValue), @CurrentTransactionId + 1); + SET @MaxTransactionId = (SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsCompleted = 1 + AND SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + AND SurrogateIdRangeFirstValue < @MinNotCompletedTransactionId + ORDER BY SurrogateIdRangeFirstValue DESC); + IF @MaxTransactionId >= @MinTransactionId + BEGIN + UPDATE A + SET IsVisible = 1, + VisibleDate = getUTCdate() + FROM dbo.Transactions AS A WITH (INDEX (1)) + WHERE SurrogateIdRangeFirstValue BETWEEN @MinTransactionId AND @CurrentTransactionId + AND SurrogateIdRangeFirstValue <= @MaxTransactionId; + SET @AffectedRows += @@rowcount; + END + SET @msg = 'Min=' + CONVERT (VARCHAR, @MinTransactionId) + ' C=' + CONVERT (VARCHAR, @CurrentTransactionId) + ' MinNC=' + CONVERT (VARCHAR, @MinNotCompletedTransactionId) + ' Max=' + CONVERT (VARCHAR, @MaxTransactionId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows, @Text = @msg; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesBeginTransaction +@Count INT, @TransactionId BIGINT OUTPUT, @SequenceRangeFirstValue INT=NULL OUTPUT, @HeartbeatDate DATETIME=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesBeginTransaction', @Mode AS VARCHAR (200) = 'Cnt=' + CONVERT (VARCHAR, @Count), @st AS DATETIME = getUTCdate(), @FirstValueVar AS SQL_VARIANT, @LastValueVar AS SQL_VARIANT; +BEGIN TRY + SET @TransactionId = NULL; + IF @@trancount > 0 + RAISERROR ('MergeResourcesBeginTransaction cannot be called inside outer transaction.', 18, 127); + SET @FirstValueVar = NULL; + WHILE @FirstValueVar IS NULL + BEGIN + EXECUTE sys.sp_sequence_get_range @sequence_name = 'dbo.ResourceSurrogateIdUniquifierSequence', @range_size = @Count, @range_first_value = @FirstValueVar OUTPUT, @range_last_value = @LastValueVar OUTPUT; + SET @SequenceRangeFirstValue = CONVERT (INT, @FirstValueVar); + IF @SequenceRangeFirstValue > CONVERT (INT, @LastValueVar) + SET @FirstValueVar = NULL; + END + SET @TransactionId = datediff_big(millisecond, '0001-01-01', sysUTCdatetime()) * 80000 + @SequenceRangeFirstValue; + INSERT INTO dbo.Transactions (SurrogateIdRangeFirstValue, SurrogateIdRangeLastValue, HeartbeatDate) + SELECT @TransactionId, + @TransactionId + @Count - 1, + isnull(@HeartbeatDate, getUTCdate()); +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesCommitTransaction +@TransactionId BIGINT, @FailureReason VARCHAR (MAX)=NULL, @OverrideIsControlledByClientCheck BIT=0 +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesCommitTransaction', @st AS DATETIME = getUTCdate(), @InitialTranCount AS INT = @@trancount, @IsCompletedBefore AS BIT, @Rows AS INT, @msg AS VARCHAR (1000); +DECLARE @Mode AS VARCHAR (200) = 'TR=' + CONVERT (VARCHAR, @TransactionId) + ' OC=' + isnull(CONVERT (VARCHAR, @OverrideIsControlledByClientCheck), 'NULL'); +BEGIN TRY + IF @InitialTranCount = 0 + BEGIN TRANSACTION; + UPDATE dbo.Transactions + SET IsCompleted = 1, + @IsCompletedBefore = IsCompleted, + EndDate = getUTCdate(), + IsSuccess = CASE WHEN @FailureReason IS NULL THEN 1 ELSE 0 END, + FailureReason = @FailureReason + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND (IsControlledByClient = 1 + OR @OverrideIsControlledByClientCheck = 1); + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + SET @msg = 'Transaction [' + CONVERT (VARCHAR (20), @TransactionId) + '] is not controlled by client or does not exist.'; + RAISERROR (@msg, 18, 127); + END + IF @IsCompletedBefore = 1 + BEGIN + IF @InitialTranCount = 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows, @Target = '@IsCompletedBefore', @Text = '=1'; + RETURN; + END + IF @InitialTranCount = 0 + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @InitialTranCount = 0 + AND @@trancount > 0 + ROLLBACK; + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory +@TransactionId BIGINT, @AffectedRows INT=NULL OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(), @TypeId AS SMALLINT; +SET @AffectedRows = 0; +BEGIN TRY + DECLARE @Types TABLE ( + TypeId SMALLINT PRIMARY KEY, + Name VARCHAR (100)); + INSERT INTO @Types + EXECUTE dbo.GetUsedResourceTypes ; + WHILE EXISTS (SELECT * + FROM @Types) + BEGIN + SET @TypeId = (SELECT TOP 1 TypeId + FROM @Types + ORDER BY TypeId); + DELETE dbo.Resource + WHERE ResourceTypeId = @TypeId + AND HistoryTransactionId = @TransactionId + AND RawResource = 0xF; + SET @AffectedRows += @@rowcount; + DELETE @Types + WHERE TypeId = @TypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @AffectedRows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesGetTimeoutTransactions +@TimeoutSec INT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'T=' + CONVERT (VARCHAR, @TimeoutSec), @st AS DATETIME = getUTCdate(), @MinTransactionId AS BIGINT; +BEGIN TRY + EXECUTE dbo.MergeResourcesGetTransactionVisibility @MinTransactionId OUTPUT; + SELECT SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE SurrogateIdRangeFirstValue > @MinTransactionId + AND IsCompleted = 0 + AND datediff(second, HeartbeatDate, getUTCdate()) > @TimeoutSec + ORDER BY SurrogateIdRangeFirstValue; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesGetTransactionVisibility +@TransactionId BIGINT OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = '', @st AS DATETIME = getUTCdate(); +SET @TransactionId = isnull((SELECT TOP 1 SurrogateIdRangeFirstValue + FROM dbo.Transactions + WHERE IsVisible = 1 + ORDER BY SurrogateIdRangeFirstValue DESC), -1); +EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount, @Text = @TransactionId; + +GO +CREATE PROCEDURE dbo.MergeResourcesPutTransactionHeartbeat +@TransactionId BIGINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'MergeResourcesPutTransactionHeartbeat', @Mode AS VARCHAR (100) = 'TR=' + CONVERT (VARCHAR, @TransactionId); +BEGIN TRY + UPDATE dbo.Transactions + SET HeartbeatDate = getUTCdate() + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND IsControlledByClient = 1; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.MergeResourcesPutTransactionInvisibleHistory +@TransactionId BIGINT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (100) = 'TR=' + CONVERT (VARCHAR, @TransactionId), @st AS DATETIME = getUTCdate(); +BEGIN TRY + UPDATE dbo.Transactions + SET InvisibleHistoryRemovedDate = getUTCdate() + WHERE SurrogateIdRangeFirstValue = @TransactionId + AND InvisibleHistoryRemovedDate IS NULL; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobCancelation +@QueueType TINYINT, @GroupId BIGINT=NULL, @JobId BIGINT=NULL +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobCancelation', @Mode AS VARCHAR (100) = 'Q=' + isnull(CONVERT (VARCHAR, @QueueType), 'NULL') + ' G=' + isnull(CONVERT (VARCHAR, @GroupId), 'NULL') + ' J=' + isnull(CONVERT (VARCHAR, @JobId), 'NULL'), @st AS DATETIME = getUTCdate(), @Rows AS INT, @PartitionId AS TINYINT = @JobId % 16; +BEGIN TRY + IF @JobId IS NULL + AND @GroupId IS NULL + RAISERROR ('@JobId = NULL and @GroupId = NULL', 18, 127); + IF @JobId IS NOT NULL + BEGIN + UPDATE dbo.JobQueue + SET Status = 4, + EndDate = getUTCdate(), + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()) + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 0; + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + UPDATE dbo.JobQueue + SET CancelRequested = 1 + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1; + SET @Rows = @@rowcount; + END + END + ELSE + BEGIN + UPDATE dbo.JobQueue + SET Status = 4, + EndDate = getUTCdate(), + Version = datediff_big(millisecond, '0001-01-01', getUTCdate()) + WHERE QueueType = @QueueType + AND GroupId = @GroupId + AND Status = 0; + SET @Rows = @@rowcount; + UPDATE dbo.JobQueue + SET CancelRequested = 1 + WHERE QueueType = @QueueType + AND GroupId = @GroupId + AND Status = 1; + SET @Rows += @@rowcount; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobHeartbeat +@QueueType TINYINT, @JobId BIGINT, @Version BIGINT, @Data BIGINT=NULL, @CancelRequested BIT=0 OUTPUT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobHeartbeat', @Mode AS VARCHAR (100), @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT = @JobId % 16; +SET @Mode = 'Q=' + CONVERT (VARCHAR, @QueueType) + ' J=' + CONVERT (VARCHAR, @JobId) + ' P=' + CONVERT (VARCHAR, @PartitionId) + ' V=' + CONVERT (VARCHAR, @Version) + ' D=' + isnull(CONVERT (VARCHAR, @Data), 'NULL'); +BEGIN TRY + UPDATE dbo.JobQueue + SET @CancelRequested = CancelRequested, + HeartbeatDate = getUTCdate() + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1 + AND Version = @Version; + SET @Rows = @@rowcount; + IF @Rows = 0 + AND NOT EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Version = @Version + AND Status IN (2, 3, 4)) + BEGIN + IF EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId) + THROW 50412, 'Precondition failed', 1; + ELSE + THROW 50404, 'Job record not found', 1; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.PutJobStatus +@QueueType TINYINT, @JobId BIGINT, @Version BIGINT, @Failed BIT, @Data BIGINT, @FinalResult VARCHAR (MAX), @RequestCancellationOnFailure BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'PutJobStatus', @Mode AS VARCHAR (100), @st AS DATETIME = getUTCdate(), @Rows AS INT = 0, @PartitionId AS TINYINT = @JobId % 16, @GroupId AS BIGINT; +SET @Mode = 'Q=' + CONVERT (VARCHAR, @QueueType) + ' J=' + CONVERT (VARCHAR, @JobId) + ' P=' + CONVERT (VARCHAR, @PartitionId) + ' V=' + CONVERT (VARCHAR, @Version) + ' F=' + CONVERT (VARCHAR, @Failed) + ' R=' + isnull(@FinalResult, 'NULL'); +BEGIN TRY + UPDATE dbo.JobQueue + SET EndDate = getUTCdate(), + Status = CASE WHEN @Failed = 1 THEN 3 WHEN CancelRequested = 1 THEN 4 ELSE 2 END, + Data = @Data, + Result = @FinalResult, + @GroupId = GroupId + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Status = 1 + AND Version = @Version; + SET @Rows = @@rowcount; + IF @Rows = 0 + BEGIN + SET @GroupId = (SELECT GroupId + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId + AND Version = @Version + AND Status IN (2, 3, 4)); + IF @GroupId IS NULL + IF EXISTS (SELECT * + FROM dbo.JobQueue + WHERE QueueType = @QueueType + AND PartitionId = @PartitionId + AND JobId = @JobId) + THROW 50412, 'Precondition failed', 1; + ELSE + THROW 50404, 'Job record not found', 1; + END + IF @Failed = 1 + AND @RequestCancellationOnFailure = 1 + EXECUTE dbo.PutJobCancelation @QueueType = @QueueType, @GroupId = @GroupId; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; + THROW; +END CATCH + +GO +CREATE OR ALTER PROCEDURE dbo.RemovePartitionFromResourceChanges_2 +@partitionNumberToSwitchOut INT, @partitionBoundaryToMerge DATETIME2 (7) +AS +BEGIN + TRUNCATE TABLE dbo.ResourceChangeDataStaging; + ALTER TABLE dbo.ResourceChangeData SWITCH PARTITION @partitionNumberToSwitchOut TO dbo.ResourceChangeDataStaging; + ALTER PARTITION FUNCTION PartitionFunction_ResourceChangeData_Timestamp( ) + MERGE RANGE (@partitionBoundaryToMerge); + TRUNCATE TABLE dbo.ResourceChangeDataStaging; +END + +GO +CREATE PROCEDURE dbo.SwitchPartitionsIn +@Tbl VARCHAR (100) +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsIn', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL'), @st AS DATETIME = getUTCdate(), @ResourceTypeId AS SMALLINT, @Rows AS BIGINT, @Txt AS VARCHAR (1000), @TblInt AS VARCHAR (100), @Ind AS VARCHAR (200), @IndId AS INT, @DataComp AS VARCHAR (100); +DECLARE @Indexes TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200)); +DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT index_id, + name + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND is_disabled = 1; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Indexes) + BEGIN + SELECT TOP 1 @IndId = IndId, + @Ind = name + FROM @Indexes + ORDER BY IndId; + SET @DataComp = CASE WHEN (SELECT PropertyValue + FROM dbo.IndexProperties + WHERE TableName = @Tbl + AND IndexName = @Ind) = 'PAGE' THEN ' PARTITION = ALL WITH (DATA_COMPRESSION = PAGE)' ELSE '' END; + SET @Txt = 'IF EXISTS (SELECT * FROM sys.indexes WHERE object_id = object_id(''' + @Tbl + ''') AND name = ''' + @Ind + ''' AND is_disabled = 1) ALTER INDEX ' + @Ind + ' ON dbo.' + @Tbl + ' REBUILD' + @DataComp; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Ind, @Action = 'Rebuild', @Text = @Txt; + DELETE @Indexes + WHERE IndId = @IndId; + END + INSERT INTO @ResourceTypes + SELECT CONVERT (SMALLINT, substring(name, charindex('_', name) + 1, 6)) AS ResourceTypeId + FROM sys.objects AS O + WHERE name LIKE @Tbl + '[_]%' + AND EXISTS (SELECT * + FROM sysindexes + WHERE id = O.object_id + AND indid IN (0, 1) + AND rows > 0); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '#ResourceTypes', @Action = 'Select Into', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId + FROM @ResourceTypes); + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt; + SET @Txt = 'ALTER TABLE dbo.' + @TblInt + ' SWITCH TO dbo.' + @Tbl + ' PARTITION $partition.PartitionFunction_ResourceTypeId(' + CONVERT (VARCHAR, @ResourceTypeId) + ')'; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch in start', @Text = @Txt; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch in', @Text = @Txt; + IF EXISTS (SELECT * + FROM sysindexes + WHERE id = object_id(@TblInt) + AND rows > 0) + BEGIN + SET @Txt = @TblInt + ' is not empty after switch'; + RAISERROR (@Txt, 18, 127); + END + EXECUTE ('DROP TABLE dbo.' + @TblInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Drop'; + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsInAllTables +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsInAllTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId', @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = 1, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SET @Tbl = (SELECT TOP 1 name + FROM @Tables + ORDER BY name); + EXECUTE dbo.SwitchPartitionsIn @Tbl = @Tbl; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'SwitchPartitionsIn', @Action = 'Execute', @Text = @Tbl; + DELETE @Tables + WHERE name = @Tbl; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsOut +@Tbl VARCHAR (100), @RebuildClustered BIT +WITH EXECUTE AS 'dbo' +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsOut', @Mode AS VARCHAR (200) = 'Tbl=' + isnull(@Tbl, 'NULL') + ' ND=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @ResourceTypeId AS SMALLINT, @Rows AS BIGINT, @Txt AS VARCHAR (MAX), @TblInt AS VARCHAR (100), @IndId AS INT, @Ind AS VARCHAR (200), @Name AS VARCHAR (100), @checkName AS VARCHAR (200), @definition AS VARCHAR (200); +DECLARE @Indexes TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200), + IsDisabled BIT ); +DECLARE @IndexesRT TABLE ( + IndId INT PRIMARY KEY, + name VARCHAR (200), + IsDisabled BIT ); +DECLARE @ResourceTypes TABLE ( + ResourceTypeId SMALLINT PRIMARY KEY, + partition_number_roundtrip INT , + partition_number INT , + row_count BIGINT ); +DECLARE @Names TABLE ( + name VARCHAR (100) PRIMARY KEY); +DECLARE @CheckConstraints TABLE ( + CheckName VARCHAR (200), + CheckDefinition VARCHAR (200)); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + IF @Tbl IS NULL + RAISERROR ('@Tbl IS NULL', 18, 127); + IF @RebuildClustered IS NULL + RAISERROR ('@RebuildClustered IS NULL', 18, 127); + INSERT INTO @Indexes + SELECT index_id, + name, + is_disabled + FROM sys.indexes + WHERE object_id = object_id(@Tbl) + AND (is_disabled = 0 + OR @RebuildClustered = 1); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Insert', @Rows = @@rowcount; + INSERT INTO @ResourceTypes + SELECT partition_number - 1 AS ResourceTypeId, + $PARTITION.PartitionFunction_ResourceTypeId (partition_number - 1) AS partition_number_roundtrip, + partition_number, + row_count + FROM sys.dm_db_partition_stats + WHERE object_id = object_id(@Tbl) + AND index_id = 1 + AND row_count > 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@ResourceTypes', @Action = 'Insert', @Rows = @@rowcount, @Text = 'For partition switch'; + IF EXISTS (SELECT * + FROM @ResourceTypes + WHERE partition_number_roundtrip <> partition_number) + RAISERROR ('Partition sanity check failed', 18, 127); + WHILE EXISTS (SELECT * + FROM @ResourceTypes) + BEGIN + SELECT TOP 1 @ResourceTypeId = ResourceTypeId, + @Rows = row_count + FROM @ResourceTypes + ORDER BY ResourceTypeId; + SET @TblInt = @Tbl + '_' + CONVERT (VARCHAR, @ResourceTypeId); + SET @Txt = 'Starting @ResourceTypeId=' + CONVERT (VARCHAR, @ResourceTypeId) + ' row_count=' + CONVERT (VARCHAR, @Rows); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Text = @Txt; + IF NOT EXISTS (SELECT * + FROM sysindexes + WHERE id = object_id(@TblInt) + AND rows > 0) + BEGIN + IF object_id(@TblInt) IS NOT NULL + BEGIN + EXECUTE ('DROP TABLE dbo.' + @TblInt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Drop'; + END + EXECUTE ('SELECT * INTO dbo.' + @TblInt + ' FROM dbo.' + @Tbl + ' WHERE 1 = 2'); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Select Into', @Rows = @@rowcount; + DELETE @CheckConstraints; + INSERT INTO @CheckConstraints + SELECT name, + definition + FROM sys.check_constraints + WHERE parent_object_id = object_id(@Tbl); + WHILE EXISTS (SELECT * + FROM @CheckConstraints) + BEGIN + SELECT TOP 1 @checkName = CheckName, + @definition = CheckDefinition + FROM @CheckConstraints; + SET @Txt = 'ALTER TABLE ' + @TblInt + ' ADD CHECK ' + @definition; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'ALTER', @Text = @Txt; + DELETE @CheckConstraints + WHERE CheckName = @checkName; + END + DELETE @Names; + INSERT INTO @Names + SELECT name + FROM sys.columns + WHERE object_id = object_id(@Tbl) + AND is_sparse = 1; + WHILE EXISTS (SELECT * + FROM @Names) + BEGIN + SET @Name = (SELECT TOP 1 name + FROM @Names + ORDER BY name); + SET @Txt = (SELECT 'ALTER TABLE dbo.' + @TblInt + ' ALTER COLUMN ' + @Name + ' ' + T.name + '(' + CONVERT (VARCHAR, C.precision) + ',' + CONVERT (VARCHAR, C.scale) + ') SPARSE NULL' + FROM sys.types AS T + INNER JOIN + sys.columns AS C + ON C.system_type_id = T.system_type_id + WHERE C.object_id = object_id(@Tbl) + AND C.name = @Name); + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'ALTER', @Text = @Txt; + DELETE @Names + WHERE name = @Name; + END + END + INSERT INTO @IndexesRT + SELECT * + FROM @Indexes + WHERE IsDisabled = 0; + WHILE EXISTS (SELECT * + FROM @IndexesRT) + BEGIN + SELECT TOP 1 @IndId = IndId, + @Ind = name + FROM @IndexesRT + ORDER BY IndId; + IF NOT EXISTS (SELECT * + FROM sys.indexes + WHERE object_id = object_id(@TblInt) + AND name = @Ind) + BEGIN + EXECUTE dbo.GetIndexCommands @Tbl = @Tbl, @Ind = @Ind, @AddPartClause = 0, @IncludeClustered = 1, @Txt = @Txt OUTPUT; + SET @Txt = replace(@Txt, '[' + @Tbl + ']', @TblInt); + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @TblInt, @Action = 'Create Index', @Text = @Txt; + END + DELETE @IndexesRT + WHERE IndId = @IndId; + END + SET @Txt = 'ALTER TABLE dbo.' + @TblInt + ' ADD CHECK (ResourceTypeId >= ' + CONVERT (VARCHAR, @ResourceTypeId) + ' AND ResourceTypeId < ' + CONVERT (VARCHAR, @ResourceTypeId) + ' + 1)'; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Add check', @Text = @Txt; + SET @Txt = 'ALTER TABLE dbo.' + @Tbl + ' SWITCH PARTITION $partition.PartitionFunction_ResourceTypeId(' + CONVERT (VARCHAR, @ResourceTypeId) + ') TO dbo.' + @TblInt; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch out start', @Text = @Txt; + EXECUTE (@Txt); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = @Tbl, @Action = 'Switch out end', @Text = @Txt; + DELETE @ResourceTypes + WHERE ResourceTypeId = @ResourceTypeId; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.SwitchPartitionsOutAllTables +@RebuildClustered BIT +AS +SET NOCOUNT ON; +DECLARE @SP AS VARCHAR (100) = 'SwitchPartitionsOutAllTables', @Mode AS VARCHAR (200) = 'PS=PartitionScheme_ResourceTypeId ND=' + isnull(CONVERT (VARCHAR, @RebuildClustered), 'NULL'), @st AS DATETIME = getUTCdate(), @Tbl AS VARCHAR (100); +BEGIN TRY + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; + DECLARE @Tables TABLE ( + name VARCHAR (100) PRIMARY KEY, + supported BIT ); + INSERT INTO @Tables + EXECUTE dbo.GetPartitionedTables @IncludeNotDisabled = @RebuildClustered, @IncludeNotSupported = 0; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Tables', @Action = 'Insert', @Rows = @@rowcount; + WHILE EXISTS (SELECT * + FROM @Tables) + BEGIN + SET @Tbl = (SELECT TOP 1 name + FROM @Tables + ORDER BY name); + EXECUTE dbo.SwitchPartitionsOut @Tbl = @Tbl, @RebuildClustered = @RebuildClustered; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'SwitchPartitionsOut', @Action = 'Execute', @Text = @Tbl; + DELETE @Tables + WHERE name = @Tbl; + END + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; +END TRY +BEGIN CATCH + IF error_number() = 1750 + THROW; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +GO +CREATE OR ALTER PROCEDURE dbo.UpdateEventAgentCheckpoint +@CheckpointId VARCHAR (64), @LastProcessedDateTime DATETIMEOFFSET (7)=NULL, @LastProcessedIdentifier VARCHAR (64)=NULL +AS +BEGIN + IF EXISTS (SELECT * + FROM dbo.EventAgentCheckpoint + WHERE CheckpointId = @CheckpointId) + UPDATE dbo.EventAgentCheckpoint + SET CheckpointId = @CheckpointId, + LastProcessedDateTime = @LastProcessedDateTime, + LastProcessedIdentifier = @LastProcessedIdentifier, + UpdatedOn = sysutcdatetime() + WHERE CheckpointId = @CheckpointId; + ELSE + INSERT INTO dbo.EventAgentCheckpoint (CheckpointId, LastProcessedDateTime, LastProcessedIdentifier, UpdatedOn) + VALUES (@CheckpointId, @LastProcessedDateTime, @LastProcessedIdentifier, sysutcdatetime()); +END + +GO +CREATE PROCEDURE dbo.UpdateReindexJob +@id VARCHAR (64), @status VARCHAR (10), @rawJobRecord VARCHAR (MAX), @jobVersion BINARY (8) +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +BEGIN TRANSACTION; +DECLARE @currentJobVersion AS BINARY (8); +SELECT @currentJobVersion = JobVersion +FROM dbo.ReindexJob WITH (UPDLOCK, HOLDLOCK) +WHERE Id = @id; +IF (@currentJobVersion IS NULL) + BEGIN + THROW 50404, 'Reindex job record not found', 1; + END +IF (@jobVersion <> @currentJobVersion) + BEGIN + THROW 50412, 'Precondition failed', 1; + END +DECLARE @heartbeatDateTime AS DATETIME2 (7) = SYSUTCDATETIME(); +UPDATE dbo.ReindexJob +SET Status = @status, + HeartbeatDateTime = @heartbeatDateTime, + RawJobRecord = @rawJobRecord +WHERE Id = @id; +SELECT @@DBTS; +COMMIT TRANSACTION; + +GO +CREATE PROCEDURE dbo.UpdateResourceSearchParams +@FailedResources INT=0 OUTPUT, @Resources dbo.ResourceList READONLY, @ResourceWriteClaims dbo.ResourceWriteClaimList READONLY, @ReferenceSearchParams dbo.ReferenceSearchParamList READONLY, @TokenSearchParams dbo.TokenSearchParamList READONLY, @TokenTexts dbo.TokenTextList READONLY, @StringSearchParams dbo.StringSearchParamList READONLY, @UriSearchParams dbo.UriSearchParamList READONLY, @NumberSearchParams dbo.NumberSearchParamList READONLY, @QuantitySearchParams dbo.QuantitySearchParamList READONLY, @DateTimeSearchParams dbo.DateTimeSearchParamList READONLY, @ReferenceTokenCompositeSearchParams dbo.ReferenceTokenCompositeSearchParamList READONLY, @TokenTokenCompositeSearchParams dbo.TokenTokenCompositeSearchParamList READONLY, @TokenDateTimeCompositeSearchParams dbo.TokenDateTimeCompositeSearchParamList READONLY, @TokenQuantityCompositeSearchParams dbo.TokenQuantityCompositeSearchParamList READONLY, @TokenStringCompositeSearchParams dbo.TokenStringCompositeSearchParamList READONLY, @TokenNumberNumberCompositeSearchParams dbo.TokenNumberNumberCompositeSearchParamList READONLY +AS +SET NOCOUNT ON; +DECLARE @st AS DATETIME = getUTCdate(), @SP AS VARCHAR (100) = object_name(@@procid), @Mode AS VARCHAR (200) = isnull((SELECT 'RT=[' + CONVERT (VARCHAR, min(ResourceTypeId)) + ',' + CONVERT (VARCHAR, max(ResourceTypeId)) + '] Sur=[' + CONVERT (VARCHAR, min(ResourceSurrogateId)) + ',' + CONVERT (VARCHAR, max(ResourceSurrogateId)) + '] V=' + CONVERT (VARCHAR, max(Version)) + ' Rows=' + CONVERT (VARCHAR, count(*)) + FROM @Resources), 'Input=Empty'), @Rows AS INT; +BEGIN TRY + DECLARE @Ids TABLE ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL); + BEGIN TRANSACTION; + UPDATE B + SET SearchParamHash = A.SearchParamHash + OUTPUT deleted.ResourceTypeId, deleted.ResourceSurrogateId INTO @Ids + FROM @Resources AS A + INNER JOIN + dbo.Resource AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE B.IsHistory = 0; + SET @Rows = @@rowcount; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ResourceWriteClaim AS B + ON B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ReferenceSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenText AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.StringSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.UriSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.NumberSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.QuantitySearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.DateTimeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.ReferenceTokenCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenTokenCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenDateTimeCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenQuantityCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenStringCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + DELETE B + FROM @Ids AS A + INNER JOIN + dbo.TokenNumberNumberCompositeSearchParam AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId; + INSERT INTO dbo.ResourceWriteClaim (ResourceSurrogateId, ClaimTypeId, ClaimValue) + SELECT ResourceSurrogateId, + ClaimTypeId, + ClaimValue + FROM @ResourceWriteClaims; + INSERT INTO dbo.ReferenceSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId, ReferenceResourceVersion) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri, + ReferenceResourceTypeId, + ReferenceResourceId, + ReferenceResourceVersion + FROM @ReferenceSearchParams; + INSERT INTO dbo.TokenSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, Code, CodeOverflow) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + Code, + CodeOverflow + FROM @TokenSearchParams; + INSERT INTO dbo.TokenText (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text + FROM @TokenTexts; + INSERT INTO dbo.StringSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Text, TextOverflow, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Text, + TextOverflow, + IsMin, + IsMax + FROM @StringSearchParams; + INSERT INTO dbo.UriSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + Uri + FROM @UriSearchParams; + INSERT INTO dbo.NumberSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SingleValue, + LowValue, + HighValue + FROM @NumberSearchParams; + INSERT INTO dbo.QuantitySearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId, QuantityCodeId, SingleValue, LowValue, HighValue) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId, + QuantityCodeId, + SingleValue, + LowValue, + HighValue + FROM @QuantitySearchParams; + INSERT INTO dbo.DateTimeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, StartDateTime, EndDateTime, IsLongerThanADay, IsMin, IsMax) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + StartDateTime, + EndDateTime, + IsLongerThanADay, + IsMin, + IsMax + FROM @DateTimeSearchParams; + INSERT INTO dbo.ReferenceTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri1, ReferenceResourceTypeId1, ReferenceResourceId1, ReferenceResourceVersion1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + BaseUri1, + ReferenceResourceTypeId1, + ReferenceResourceId1, + ReferenceResourceVersion1, + SystemId2, + Code2, + CodeOverflow2 + FROM @ReferenceTokenCompositeSearchParams; + INSERT INTO dbo.TokenTokenCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SystemId2, Code2, CodeOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SystemId2, + Code2, + CodeOverflow2 + FROM @TokenTokenCompositeSearchParams; + INSERT INTO dbo.TokenDateTimeCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, StartDateTime2, EndDateTime2, IsLongerThanADay2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + StartDateTime2, + EndDateTime2, + IsLongerThanADay2 + FROM @TokenDateTimeCompositeSearchParams; + INSERT INTO dbo.TokenQuantityCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, SystemId2, QuantityCodeId2, LowValue2, HighValue2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + SystemId2, + QuantityCodeId2, + LowValue2, + HighValue2 + FROM @TokenQuantityCompositeSearchParams; + INSERT INTO dbo.TokenStringCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, Text2, TextOverflow2) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + Text2, + TextOverflow2 + FROM @TokenStringCompositeSearchParams; + INSERT INTO dbo.TokenNumberNumberCompositeSearchParam (ResourceTypeId, ResourceSurrogateId, SearchParamId, SystemId1, Code1, CodeOverflow1, SingleValue2, LowValue2, HighValue2, SingleValue3, LowValue3, HighValue3, HasRange) + SELECT ResourceTypeId, + ResourceSurrogateId, + SearchParamId, + SystemId1, + Code1, + CodeOverflow1, + SingleValue2, + LowValue2, + HighValue2, + SingleValue3, + LowValue3, + HighValue3, + HasRange + FROM @TokenNumberNumberCompositeSearchParams; + COMMIT TRANSACTION; + SET @FailedResources = (SELECT count(*) + FROM @Resources) - @Rows; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; +END TRY +BEGIN CATCH + IF @@trancount > 0 + ROLLBACK; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error', @Start = @st; + THROW; +END CATCH + +GO +CREATE PROCEDURE dbo.UpsertSearchParams +@searchParams dbo.SearchParamTableType_2 READONLY +AS +SET NOCOUNT ON; +SET XACT_ABORT ON; +SET TRANSACTION ISOLATION LEVEL SERIALIZABLE; +BEGIN TRANSACTION; +DECLARE @lastUpdated AS DATETIMEOFFSET (7) = SYSDATETIMEOFFSET(); +DECLARE @summaryOfChanges TABLE ( + Uri VARCHAR (128) COLLATE Latin1_General_100_CS_AS NOT NULL, + Action VARCHAR (20) NOT NULL); +MERGE INTO dbo.SearchParam WITH (TABLOCKX) + AS target +USING @searchParams AS source ON target.Uri = source.Uri +WHEN MATCHED THEN UPDATE +SET Status = source.Status, + LastUpdated = @lastUpdated, + IsPartiallySupported = source.IsPartiallySupported +WHEN NOT MATCHED BY TARGET THEN INSERT (Uri, Status, LastUpdated, IsPartiallySupported) VALUES (source.Uri, source.Status, @lastUpdated, source.IsPartiallySupported) +OUTPUT source.Uri, $ACTION INTO @summaryOfChanges; +SELECT SearchParamId, + SearchParam.Uri +FROM dbo.SearchParam AS searchParam + INNER JOIN + @summaryOfChanges AS upsertedSearchParam + ON searchParam.Uri = upsertedSearchParam.Uri +WHERE upsertedSearchParam.Action = 'INSERT'; +COMMIT TRANSACTION; + +GO +CREATE VIEW dbo.CurrentResource +AS +SELECT * +FROM dbo.Resource +WHERE IsHistory = 0; + +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs index 309a6ff48d..e633808e9d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs @@ -93,5 +93,6 @@ public enum SchemaVersion V81 = 81, V82 = 82, V83 = 83, + V84 = 84, } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs index 17593e9b0f..92d8be3e8a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs @@ -7,9 +7,9 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema { public static class SchemaVersionConstants { - public const int Min = (int)SchemaVersion.V80; - public const int Max = (int)SchemaVersion.V83; - public const int MinForUpgrade = (int)SchemaVersion.V80; // this is used for upgrade tests only + public const int Min = (int)SchemaVersion.V83; + public const int Max = (int)SchemaVersion.V84; + public const int MinForUpgrade = (int)SchemaVersion.V83; // this is used for upgrade tests only public const int SearchParameterStatusSchemaVersion = (int)SchemaVersion.V6; public const int SupportForReferencesWithMissingTypeVersion = (int)SchemaVersion.V7; public const int SearchParameterHashSchemaVersion = (int)SchemaVersion.V8; @@ -32,6 +32,7 @@ public static class SchemaVersionConstants public const int ExportTimeTravel = (int)SchemaVersion.V44; public const int Merge = (int)SchemaVersion.V50; public const int IncrementalImport = (int)SchemaVersion.V53; + public const int LakePrerequisite = (int)SchemaVersion.V84; // It is currently used in Azure Healthcare APIs. public const int ParameterizedRemovePartitionFromResourceChangesVersion = (int)SchemaVersion.V21; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql index df6c3891df..4e8bc838ee 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql @@ -19,6 +19,6 @@ Go INSERT INTO dbo.SchemaVersion VALUES - (83, 'started') + (84, 'started') Go diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource_0.sql similarity index 71% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql rename to src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource_0.sql index e880a6b995..f550f6929b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/Resource_0.sql @@ -1,4 +1,22 @@ -CREATE TABLE dbo.Resource +CREATE TABLE dbo.CurrentResource -- This is replaced by view CurrentResource +( + ResourceTypeId smallint NOT NULL, + ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL, + Version int NOT NULL, + IsHistory bit NOT NULL, + ResourceSurrogateId bigint NOT NULL, + IsDeleted bit NOT NULL, + RequestMethod varchar(10) NULL, + RawResource varbinary(max) NOT NULL, + IsRawResourceMetaSet bit NOT NULL, + SearchParamHash varchar(64) NULL, + TransactionId bigint NULL, + HistoryTransactionId bigint NULL +) +GO +DROP TABLE dbo.CurrentResource +GO +CREATE TABLE dbo.Resource ( ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL, @@ -50,3 +68,4 @@ CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId O ) WHERE IsHistory = 0 AND IsDeleted = 0 ON PartitionScheme_ResourceTypeId(ResourceTypeId) +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql new file mode 100644 index 0000000000..d4959610f0 --- /dev/null +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql @@ -0,0 +1,6 @@ +CREATE VIEW dbo.CurrentResource +AS +SELECT * + FROM dbo.Resource + WHERE IsHistory = 0 +GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index e229ae7239..618cd3c37c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -218,21 +218,24 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions if (selectingFromResourceTable) { - StringBuilder.Append("FROM ").Append(VLatest.Resource).Append(" ").Append(resourceTableAlias); - if (expression.SearchParamTableExpressions.Count == 0 && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.SoftDeleted) && expression.ResourceTableExpressions.Any(e => e.AcceptVisitor(ExpressionContainsParameterVisitor.Instance, SearchParameterNames.ResourceType)) && !expression.ResourceTableExpressions.Any(e => e.AcceptVisitor(ExpressionContainsParameterVisitor.Instance, SearchParameterNames.Id))) { + StringBuilder.Append("FROM ").Append(VLatest.Resource).Append(" ").AppendLine(resourceTableAlias); + // If this is a simple search over a resource type (like GET /Observation) // make sure the optimizer does not decide to do a scan on the clustered index, since we have an index specifically for this common case StringBuilder.Append(" WITH (INDEX(").Append(VLatest.Resource.IX_Resource_ResourceTypeId_ResourceSurrgateId).AppendLine("))"); } else { - StringBuilder.AppendLine(); + var latestAndLakePrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) + && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) + && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; + StringBuilder.Append("FROM ").Append(latestAndLakePrereq ? VLatest.CurrentResource : VLatest.Resource).Append(" ").AppendLine(resourceTableAlias); } if (expression.SearchParamTableExpressions.Count > 0) @@ -251,7 +254,7 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions denormalizedPredicate.AcceptVisitor(ResourceTableSearchParameterQueryGenerator.Instance, GetContext()); } - AppendHistoryClause(delimitedClause, context.ResourceVersionTypes); // This does not hurt today, but will be neded with resource history separation + AppendHistoryClause(delimitedClause, context.ResourceVersionTypes); AppendDeletedClause(delimitedClause, context.ResourceVersionTypes); } @@ -542,6 +545,9 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpression, SearchOptions context) { int predecessorIndex = FindRestrictingPredecessorTableExpressionIndex(); + var latestAndPrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) + && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) + && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; // In the case the query contains a UNION operator, the following CTE must join the latest Union CTE // where all data is aggregated. @@ -551,7 +557,7 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre StringBuilder.Append("SELECT ") .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") // SELECT and FROM can be on same line only for singe line statements - .Append("FROM ").AppendLine(VLatest.Resource) + .Append("FROM ").AppendLine(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource) .Append(_joinShift).Append("JOIN ").Append(cte) .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); @@ -572,7 +578,7 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre StringBuilder.Append("SELECT ") .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") - .Append("FROM ").AppendLine(VLatest.Resource); + .Append("FROM ").AppendLine(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -682,7 +688,9 @@ private void HandleTableKindChain( string referenceTargetResourceTableAlias) { var chainedExpression = (SqlChainLinkExpression)searchParamTableExpression.Predicate; - + var latestAndPrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) + && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) + && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; StringBuilder.Append("SELECT "); if (searchParamTableExpression.ChainLevel == 1) { @@ -698,7 +706,7 @@ private void HandleTableKindChain( .Append(VLatest.Resource.ResourceTypeId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").Append(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "T1, " : "T2, ") .Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") .Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(_joinShift).Append("JOIN ").Append(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); @@ -707,7 +715,7 @@ private void HandleTableKindChain( if (expressionOnTargetHandledBySecondJoin) { const string referenceSourceResourceTableAlias = "refSourceResource"; - StringBuilder.Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) + StringBuilder.Append(_joinShift).Append("JOIN ").Append(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceSourceResourceTableAlias) .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceResourceTableAlias) .Append(" AND "); @@ -774,7 +782,9 @@ private void HandleTableKindInclude( string referenceTargetResourceTableAlias) { var includeExpression = (IncludeExpression)searchParamTableExpression.Predicate; - + var latestAndPrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) + && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) + && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; _includeCteIds = _includeCteIds ?? new List(); _includeLimitCtesByResourceType = _includeLimitCtesByResourceType ?? new Dictionary>(); _includeFromCteIds = _includeFromCteIds ?? new List(); @@ -795,7 +805,7 @@ private void HandleTableKindInclude( .AppendLine(" AS Sid1, 0 AS IsMatch "); StringBuilder.Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(_joinShift).Append("JOIN ").Append(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj index c537d49285..909f001e89 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj +++ b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj @@ -1,7 +1,7 @@  - 83 + 84 Features\Schema\Migrations\$(LatestSchemaVersion).sql @@ -43,6 +43,7 @@ + From 88f831b2da490ec8a2e9ce0fa645c744aa066517 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 19:36:23 -0800 Subject: [PATCH 056/111] nicer --- .../Features/Search/SearchOptions.cs | 2 ++ .../QueryGenerators/SqlQueryGenerator.cs | 29 +++++++------------ 2 files changed, 12 insertions(+), 19 deletions(-) diff --git a/src/Microsoft.Health.Fhir.Core/Features/Search/SearchOptions.cs b/src/Microsoft.Health.Fhir.Core/Features/Search/SearchOptions.cs index 0f04e70a94..149170fb90 100644 --- a/src/Microsoft.Health.Fhir.Core/Features/Search/SearchOptions.cs +++ b/src/Microsoft.Health.Fhir.Core/Features/Search/SearchOptions.cs @@ -124,6 +124,8 @@ internal set /// public ResourceVersionType ResourceVersionTypes { get; internal set; } = ResourceVersionType.Latest; + internal bool AddCurrentClause => ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) && !ResourceVersionTypes.HasFlag(ResourceVersionType.History); + /// /// Gets the search expression. /// diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 618cd3c37c..29cb5e9892 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -54,6 +54,7 @@ internal class SqlQueryGenerator : DefaultSqlExpressionVisitor= SchemaVersionConstants.LakePrerequisite; _reuseQueryPlans = reuseQueryPlans; if (sqlException?.Number == SqlErrorCodes.QueryProcessorNoQueryPlan) @@ -218,6 +220,7 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions if (selectingFromResourceTable) { + // TODO: Remove logic to add index hint once Lake schema is deployed. Scanning clustered index of CurrentResources is efficient. if (expression.SearchParamTableExpressions.Count == 0 && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.SoftDeleted) && @@ -232,10 +235,7 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions } else { - var latestAndLakePrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) - && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) - && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; - StringBuilder.Append("FROM ").Append(latestAndLakePrereq ? VLatest.CurrentResource : VLatest.Resource).Append(" ").AppendLine(resourceTableAlias); + StringBuilder.Append("FROM ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(" ").AppendLine(resourceTableAlias); } if (expression.SearchParamTableExpressions.Count > 0) @@ -433,7 +433,7 @@ private void HandleParamTableUnion(SearchParamTableExpression searchParamTableEx if (searchParameterExpressionPredicate != null && searchParameterExpressionPredicate.Parameter.ColumnLocation().HasFlag(SearchParameterColumnLocation.ResourceTable)) { - StringBuilder.Append("FROM ").AppendLine(new VLatest.ResourceTable()); + StringBuilder.Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource); } else { @@ -545,9 +545,6 @@ private void HandleTableKindNormal(SearchParamTableExpression searchParamTableEx private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpression, SearchOptions context) { int predecessorIndex = FindRestrictingPredecessorTableExpressionIndex(); - var latestAndPrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) - && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) - && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; // In the case the query contains a UNION operator, the following CTE must join the latest Union CTE // where all data is aggregated. @@ -557,7 +554,7 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre StringBuilder.Append("SELECT ") .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") // SELECT and FROM can be on same line only for singe line statements - .Append("FROM ").AppendLine(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource) + .Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource) .Append(_joinShift).Append("JOIN ").Append(cte) .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); @@ -578,7 +575,7 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre StringBuilder.Append("SELECT ") .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") - .Append("FROM ").AppendLine(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource); + .Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -688,9 +685,6 @@ private void HandleTableKindChain( string referenceTargetResourceTableAlias) { var chainedExpression = (SqlChainLinkExpression)searchParamTableExpression.Predicate; - var latestAndPrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) - && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) - && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; StringBuilder.Append("SELECT "); if (searchParamTableExpression.ChainLevel == 1) { @@ -706,7 +700,7 @@ private void HandleTableKindChain( .Append(VLatest.Resource.ResourceTypeId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").Append(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "T1, " : "T2, ") .Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") .Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); @@ -715,7 +709,7 @@ private void HandleTableKindChain( if (expressionOnTargetHandledBySecondJoin) { const string referenceSourceResourceTableAlias = "refSourceResource"; - StringBuilder.Append(_joinShift).Append("JOIN ").Append(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) + StringBuilder.Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceSourceResourceTableAlias) .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceResourceTableAlias) .Append(" AND "); @@ -782,9 +776,6 @@ private void HandleTableKindInclude( string referenceTargetResourceTableAlias) { var includeExpression = (IncludeExpression)searchParamTableExpression.Predicate; - var latestAndPrereq = context.ResourceVersionTypes.HasFlag(ResourceVersionType.Latest) - && !context.ResourceVersionTypes.HasFlag(ResourceVersionType.History) - && _schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; _includeCteIds = _includeCteIds ?? new List(); _includeLimitCtesByResourceType = _includeLimitCtesByResourceType ?? new Dictionary>(); _includeFromCteIds = _includeFromCteIds ?? new List(); @@ -805,7 +796,7 @@ private void HandleTableKindInclude( .AppendLine(" AS Sid1, 0 AS IsMatch "); StringBuilder.Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(latestAndPrereq ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); From 039a1481526b725226eb5266fcf40d56e51014c3 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 17 Dec 2024 19:36:53 -0800 Subject: [PATCH 057/111] spelling --- .../QueryGenerators/SqlQueryGenerator.cs | 18 +++++++++--------- 1 file changed, 9 insertions(+), 9 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 29cb5e9892..761fe662ef 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -54,7 +54,7 @@ internal class SqlQueryGenerator : DefaultSqlExpressionVisitor= SchemaVersionConstants.LakePrerequisite; + _allowCurrent = schemaInfo.Current >= SchemaVersionConstants.LakePrerequisite; _reuseQueryPlans = reuseQueryPlans; if (sqlException?.Number == SqlErrorCodes.QueryProcessorNoQueryPlan) @@ -235,7 +235,7 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions } else { - StringBuilder.Append("FROM ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(" ").AppendLine(resourceTableAlias); + StringBuilder.Append("FROM ").Append(context.AddCurrentClause && _allowCurrent ? VLatest.CurrentResource : VLatest.Resource).Append(" ").AppendLine(resourceTableAlias); } if (expression.SearchParamTableExpressions.Count > 0) @@ -433,7 +433,7 @@ private void HandleParamTableUnion(SearchParamTableExpression searchParamTableEx if (searchParameterExpressionPredicate != null && searchParameterExpressionPredicate.Parameter.ColumnLocation().HasFlag(SearchParameterColumnLocation.ResourceTable)) { - StringBuilder.Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource); + StringBuilder.Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurrent ? VLatest.CurrentResource : VLatest.Resource); } else { @@ -554,7 +554,7 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre StringBuilder.Append("SELECT ") .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") // SELECT and FROM can be on same line only for singe line statements - .Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource) + .Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurrent ? VLatest.CurrentResource : VLatest.Resource) .Append(_joinShift).Append("JOIN ").Append(cte) .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, null).Append(" = ").Append(cte).Append(".T1") .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, null).Append(" = ").Append(cte).AppendLine(".Sid1"); @@ -575,7 +575,7 @@ private void HandleTableKindAll(SearchParamTableExpression searchParamTableExpre StringBuilder.Append("SELECT ") .Append(VLatest.Resource.ResourceTypeId, null).Append(" AS T1, ") .Append(VLatest.Resource.ResourceSurrogateId, null).AppendLine(" AS Sid1") - .Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource); + .Append("FROM ").AppendLine(context.AddCurrentClause && _allowCurrent ? VLatest.CurrentResource : VLatest.Resource); using (var delimited = StringBuilder.BeginDelimitedWhereClause()) { @@ -700,7 +700,7 @@ private void HandleTableKindChain( .Append(VLatest.Resource.ResourceTypeId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").Append(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "T1, " : "T2, ") .Append(VLatest.Resource.ResourceSurrogateId, chainedExpression.Reversed && searchParamTableExpression.ChainLevel > 1 ? referenceSourceTableAlias : referenceTargetResourceTableAlias).Append(" AS ").AppendLine(chainedExpression.Reversed && searchParamTableExpression.ChainLevel == 1 ? "Sid1 " : "Sid2 ") .Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurrent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); @@ -709,7 +709,7 @@ private void HandleTableKindChain( if (expressionOnTargetHandledBySecondJoin) { const string referenceSourceResourceTableAlias = "refSourceResource"; - StringBuilder.Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) + StringBuilder.Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurrent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceSourceResourceTableAlias) .Append(" ON ").Append(VLatest.Resource.ResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceSourceResourceTableAlias) .Append(" AND ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceSurrogateId, referenceSourceResourceTableAlias) .Append(" AND "); @@ -796,7 +796,7 @@ private void HandleTableKindInclude( .AppendLine(" AS Sid1, 0 AS IsMatch "); StringBuilder.Append("FROM ").Append(VLatest.ReferenceSearchParam).Append(' ').AppendLine(referenceSourceTableAlias) - .Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) + .Append(_joinShift).Append("JOIN ").Append(context.AddCurrentClause && _allowCurrent ? VLatest.CurrentResource : VLatest.Resource).Append(' ').Append(referenceTargetResourceTableAlias) .Append(" ON ").Append(VLatest.ReferenceSearchParam.ReferenceResourceTypeId, referenceSourceTableAlias).Append(" = ").Append(VLatest.Resource.ResourceTypeId, referenceTargetResourceTableAlias) .Append(" AND ").Append(VLatest.ReferenceSearchParam.ReferenceResourceId, referenceSourceTableAlias).Append(" = ").AppendLine(VLatest.Resource.ResourceId, referenceTargetResourceTableAlias); From 37b83b0040439eebd18ddea47ee6c54109b4139a Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 18 Dec 2024 14:25:38 -0800 Subject: [PATCH 058/111] 84 -> 85 --- .../Features/Schema/Migrations/{84.diff.sql => 85.diff.sql} | 0 .../Features/Schema/Migrations/{84.sql => 85.sql} | 0 .../Features/Schema/SchemaVersion.cs | 2 +- .../Features/Schema/SchemaVersionConstants.cs | 4 ++-- .../Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql | 2 +- .../Microsoft.Health.Fhir.SqlServer.csproj | 2 +- 6 files changed, 5 insertions(+), 5 deletions(-) rename src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/{84.diff.sql => 85.diff.sql} (100%) rename src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/{84.sql => 85.sql} (100%) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql similarity index 100% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.diff.sql rename to src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql similarity index 100% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/84.sql rename to src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs index e633808e9d..3d56ed872a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersion.cs @@ -93,6 +93,6 @@ public enum SchemaVersion V81 = 81, V82 = 82, V83 = 83, - V84 = 84, + V85 = 85, } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs index d552c5fc1b..b40f06f44c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/SchemaVersionConstants.cs @@ -8,7 +8,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema public static class SchemaVersionConstants { public const int Min = (int)SchemaVersion.V83; - public const int Max = (int)SchemaVersion.V84; + public const int Max = (int)SchemaVersion.V85; public const int MinForUpgrade = (int)SchemaVersion.V80; // this is used for upgrade tests only public const int SearchParameterStatusSchemaVersion = (int)SchemaVersion.V6; public const int SupportForReferencesWithMissingTypeVersion = (int)SchemaVersion.V7; @@ -32,7 +32,7 @@ public static class SchemaVersionConstants public const int ExportTimeTravel = (int)SchemaVersion.V44; public const int Merge = (int)SchemaVersion.V50; public const int IncrementalImport = (int)SchemaVersion.V53; - public const int Lake = (int)SchemaVersion.V84; + public const int Lake = (int)SchemaVersion.V85; // It is currently used in Azure Healthcare APIs. public const int ParameterizedRemovePartitionFromResourceChangesVersion = (int)SchemaVersion.V21; diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql index 4e8bc838ee..b3634a6b06 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Scripts/TransactionCheckWithInitialiScript.sql @@ -19,6 +19,6 @@ Go INSERT INTO dbo.SchemaVersion VALUES - (84, 'started') + (85, 'started') Go diff --git a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj index 909f001e89..b5edf826d1 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj +++ b/src/Microsoft.Health.Fhir.SqlServer/Microsoft.Health.Fhir.SqlServer.csproj @@ -1,7 +1,7 @@  - 84 + 85 Features\Schema\Migrations\$(LatestSchemaVersion).sql From b975e1a3c052ae3625df925cbce43713722e15f2 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 18 Dec 2024 14:25:52 -0800 Subject: [PATCH 059/111] 85 --- .../Features/Schema/Migrations/85.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index f24d3f5c5e..37639a9c3c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -15,7 +15,7 @@ IF EXISTS (SELECT * GO INSERT INTO dbo.SchemaVersion -VALUES (84, 'started'); +VALUES (85, 'started'); CREATE PARTITION FUNCTION PartitionFunction_ResourceTypeId(SMALLINT) AS RANGE RIGHT From 2f342997e99af48a6b9c842417ee6778218c1d16 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 18 Dec 2024 15:52:06 -0800 Subject: [PATCH 060/111] 85 --- .../Features/Schema/Migrations/85.diff.sql | 62 ++++++++++ .../Features/Schema/Migrations/85.sql | 116 ++++++++---------- .../Features/Schema/Sql/Tables/0_Resource.sql | 25 +++- .../Schema/Sql/Views/CurrentResource.sql | 23 +++- 4 files changed, 157 insertions(+), 69 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index ec32791dc0..227e6362c0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -201,6 +201,47 @@ SELECT ResourceTypeId FROM dbo.ResourceTbl ') + EXECUTE(' +ALTER VIEW dbo.CurrentResource +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,ResourceId + ,NULL + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,NULL + ,NULL + FROM dbo.ResourceTbl + WHERE IsHistory = 0 + ') + EXECUTE(' ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY AS @@ -2184,6 +2225,27 @@ SELECT A.ResourceTypeId LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt GO +ALTER VIEW dbo.CurrentResource +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +GO ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT AS BEGIN diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index 63cb72b5f6..94c6dc9739 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -275,10 +275,35 @@ CREATE TYPE dbo.UriSearchParamList AS TABLE ( SearchParamId SMALLINT NOT NULL, Uri VARCHAR (256) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceSurrogateId, SearchParamId, Uri)); +CREATE TABLE dbo.CurrentResource ( + ResourceTypeId SMALLINT NOT NULL, + ResourceSurrogateId BIGINT NOT NULL, + ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ResourceIdInt BIGINT NOT NULL, + Version INT NOT NULL, + IsHistory BIT NOT NULL, + IsDeleted BIT NOT NULL, + RequestMethod VARCHAR (10) NULL, + RawResource VARBINARY (MAX) NULL, + IsRawResourceMetaSet BIT NOT NULL, + SearchParamHash VARCHAR (64) NULL, + TransactionId BIGINT NULL, + HistoryTransactionId BIGINT NULL, + FileId BIGINT NULL, + OffsetInFile INT NULL +); + + +GO +DROP TABLE dbo.CurrentResource; + + +GO CREATE TABLE dbo.Resource ( ResourceTypeId SMALLINT NOT NULL, ResourceSurrogateId BIGINT NOT NULL, ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, + ResourceIdInt BIGINT NOT NULL, Version INT NOT NULL, IsHistory BIT NOT NULL, IsDeleted BIT NOT NULL, @@ -292,6 +317,9 @@ CREATE TABLE dbo.Resource ( OffsetInFile INT NULL ); +CREATE INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId + ON Resource(ResourceTypeId); + GO DROP TABLE dbo.Resource; @@ -829,67 +857,6 @@ WITH (DATA_COMPRESSION = PAGE); CREATE CLUSTERED INDEX IXC_ResourceWriteClaim ON dbo.ResourceWriteClaim(ResourceSurrogateId, ClaimTypeId); -CREATE TABLE dbo.CurrentResource ( - ResourceTypeId SMALLINT NOT NULL, - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, - Version INT NOT NULL, - IsHistory BIT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - IsDeleted BIT NOT NULL, - RequestMethod VARCHAR (10) NULL, - RawResource VARBINARY (MAX) NOT NULL, - IsRawResourceMetaSet BIT NOT NULL, - SearchParamHash VARCHAR (64) NULL, - TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL -); - - -GO -DROP TABLE dbo.CurrentResource; - - -GO -CREATE TABLE dbo.Resource ( - ResourceTypeId SMALLINT NOT NULL, - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS NOT NULL, - Version INT NOT NULL, - IsHistory BIT NOT NULL, - ResourceSurrogateId BIGINT NOT NULL, - IsDeleted BIT NOT NULL, - RequestMethod VARCHAR (10) NULL, - RawResource VARBINARY (MAX) NOT NULL, - IsRawResourceMetaSet BIT DEFAULT 0 NOT NULL, - SearchParamHash VARCHAR (64) NULL, - TransactionId BIGINT NULL, - HistoryTransactionId BIGINT NULL CONSTRAINT PKC_Resource PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_Resource_RawResource_Length CHECK (RawResource > 0x0) -); - -ALTER TABLE dbo.Resource SET (LOCK_ESCALATION = AUTO); - -CREATE INDEX IX_ResourceTypeId_TransactionId - ON dbo.Resource(ResourceTypeId, TransactionId) WHERE TransactionId IS NOT NULL - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - -CREATE INDEX IX_ResourceTypeId_HistoryTransactionId - ON dbo.Resource(ResourceTypeId, HistoryTransactionId) WHERE HistoryTransactionId IS NOT NULL - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId_Version - ON dbo.Resource(ResourceTypeId, ResourceId, Version) - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceId - ON dbo.Resource(ResourceTypeId, ResourceId) - INCLUDE(Version, IsDeleted) WHERE IsHistory = 0 - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - -CREATE UNIQUE NONCLUSTERED INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId - ON dbo.Resource(ResourceTypeId, ResourceSurrogateId) WHERE IsHistory = 0 - AND IsDeleted = 0 - ON PartitionScheme_ResourceTypeId (ResourceTypeId); - CREATE TABLE dbo.SchemaMigrationProgress ( Timestamp DATETIME2 (3) DEFAULT CURRENT_TIMESTAMP, Message NVARCHAR (MAX) @@ -6167,9 +6134,30 @@ COMMIT TRANSACTION; GO CREATE VIEW dbo.CurrentResource AS -SELECT * -FROM dbo.Resource -WHERE IsHistory = 0; +SELECT A.ResourceTypeId, + A.ResourceSurrogateId, + ResourceId, + A.ResourceIdInt, + Version, + IsHistory, + IsDeleted, + RequestMethod, + RawResource, + IsRawResourceMetaSet, + SearchParamHash, + TransactionId, + HistoryTransactionId, + FileId, + OffsetInFile +FROM dbo.CurrentResources AS A + LEFT OUTER JOIN + dbo.RawResources AS B + ON B.ResourceTypeId = A.ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN + dbo.ResourceIdIntMap AS C + ON C.ResourceTypeId = A.ResourceTypeId + AND C.ResourceIdInt = A.ResourceIdInt; GO CREATE VIEW dbo.ReferenceSearchParam diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql index baf0200463..da41dc6111 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql @@ -1,10 +1,32 @@ -- 0 in this script name is needed to ensure that this script is executed first, so FK constraints can be created in other scripts --- Our code generator does not understand views (in the end Resource is a view), so we create a table that looks like a view and immediately drop it. +-- Our code generator does not understand views, so we create tables which look like views and immediately drop them. +CREATE TABLE dbo.CurrentResource +( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,IsHistory bit NOT NULL + ,IsDeleted bit NOT NULL + ,RequestMethod varchar(10) NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL + ,FileId bigint NULL + ,OffsetInFile int NULL +) +GO +DROP TABLE dbo.CurrentResource +GO CREATE TABLE dbo.Resource ( ResourceTypeId smallint NOT NULL ,ResourceSurrogateId bigint NOT NULL ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ResourceIdInt bigint NOT NULL ,Version int NOT NULL ,IsHistory bit NOT NULL ,IsDeleted bit NOT NULL @@ -17,6 +39,7 @@ CREATE TABLE dbo.Resource ,FileId bigint NULL ,OffsetInFile int NULL ) +CREATE INDEX IX_Resource_ResourceTypeId_ResourceSurrgateId ON Resource (ResourceTypeId) -- index definition does not matter as it is not used in new schema and left here just to generate same queries accessing old schema during upgrade. GO DROP TABLE dbo.Resource GO diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql index d4959610f0..25cb04831d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Views/CurrentResource.sql @@ -1,6 +1,21 @@ CREATE VIEW dbo.CurrentResource -AS -SELECT * - FROM dbo.Resource - WHERE IsHistory = 0 +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt GO From 0389733ff215e0f209fed7e535e7217d7eef4815 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 19 Dec 2024 16:20:50 -0800 Subject: [PATCH 061/111] Changed order of columns for clustered key on resource tables to support sort --- .../Features/Schema/Migrations/85.diff.sql | 4 ++-- .../Features/Schema/Migrations/85.sql | 4 ++-- .../Features/Schema/Sql/Tables/0_Resource.sql | 4 ++-- 3 files changed, 6 insertions(+), 6 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 227e6362c0..ff0e793edd 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -104,7 +104,7 @@ BEGIN ,FileId bigint NULL ,OffsetInFile int NULL - CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + CONSTRAINT PKC_CurrentResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) @@ -131,7 +131,7 @@ BEGIN ,FileId bigint NULL ,OffsetInFile int NULL - CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + CONSTRAINT PKC_HistoryResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index 94c6dc9739..41659bff84 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -360,7 +360,7 @@ CREATE TABLE dbo.CurrentResources ( TransactionId BIGINT NULL, HistoryTransactionId BIGINT NULL, FileId BIGINT NULL, - OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ); @@ -393,7 +393,7 @@ CREATE TABLE dbo.HistoryResources ( TransactionId BIGINT NULL, HistoryTransactionId BIGINT NULL, FileId BIGINT NULL, - OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), + OffsetInFile INT NULL CONSTRAINT PKC_HistoryResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), CONSTRAINT CH_HistoryResources_IsHistory CHECK (IsHistory = 1), CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql index da41dc6111..fa898eb339 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql @@ -82,7 +82,7 @@ CREATE TABLE dbo.CurrentResources ,FileId bigint NULL ,OffsetInFile int NULL - CONSTRAINT PKC_CurrentResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + CONSTRAINT PKC_CurrentResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) @@ -109,7 +109,7 @@ CREATE TABLE dbo.HistoryResources ,FileId bigint NULL ,OffsetInFile int NULL - CONSTRAINT PKC_HistoryResources_ResourceSurrogateId_ResourceTypeId PRIMARY KEY CLUSTERED (ResourceSurrogateId, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + CONSTRAINT PKC_HistoryResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ,CONSTRAINT U_HistoryResources_ResourceIdInt_Version_ResourceTypeId UNIQUE (ResourceIdInt, Version, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ) From 826d08b1706d29333a1fc969cb402f9fd6db1e81 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 19 Dec 2024 16:58:11 -0800 Subject: [PATCH 062/111] DELETE inside loop --- .../Features/Schema/Migrations/85.diff.sql | 3 ++- 1 file changed, 2 insertions(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index ff0e793edd..a2fe93dd89 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -1960,12 +1960,13 @@ BEGIN TRY BEGIN SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@CurrentMaxSurrogateId) + RetryResourceIdIntMapInsert: + DELETE FROM @InputIds DELETE FROM @RTs DELETE FROM @InsertedIds DELETE FROM @ExistingIds - RetryResourceIdIntMapInsert: BEGIN TRY SET @st = getUTCdate() INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId From bd453b2d3c8f629da0c02f191cd97c4dd3cd327f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 20 Dec 2024 14:25:44 -0800 Subject: [PATCH 063/111] old views always and proc to move --- .../Features/Schema/Migrations/85.diff.sql | 557 +++++++++++------- 1 file changed, 333 insertions(+), 224 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index a2fe93dd89..392992c979 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -201,47 +201,6 @@ SELECT ResourceTypeId FROM dbo.ResourceTbl ') - EXECUTE(' -ALTER VIEW dbo.CurrentResource -AS -SELECT A.ResourceTypeId - ,A.ResourceSurrogateId - ,ResourceId - ,A.ResourceIdInt - ,Version - ,IsHistory - ,IsDeleted - ,RequestMethod - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,TransactionId - ,HistoryTransactionId - ,FileId - ,OffsetInFile - FROM dbo.CurrentResources A - LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt -UNION ALL -SELECT ResourceTypeId - ,ResourceSurrogateId - ,ResourceId - ,NULL - ,Version - ,IsHistory - ,IsDeleted - ,RequestMethod - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,TransactionId - ,HistoryTransactionId - ,NULL - ,NULL - FROM dbo.ResourceTbl - WHERE IsHistory = 0 - ') - EXECUTE(' ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY AS @@ -403,6 +362,102 @@ END CATCH COMMIT TRANSACTION END GO +CREATE OR ALTER VIEW dbo.Resource +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +UNION ALL +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.HistoryResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,ResourceId + ,NULL + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,NULL + ,NULL + FROM dbo.ResourceTbl +GO +CREATE OR ALTER VIEW dbo.CurrentResource +AS +SELECT A.ResourceTypeId + ,A.ResourceSurrogateId + ,ResourceId + ,A.ResourceIdInt + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,FileId + ,OffsetInFile + FROM dbo.CurrentResources A + LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt +UNION ALL +SELECT ResourceTypeId + ,ResourceSurrogateId + ,ResourceId + ,NULL + ,Version + ,IsHistory + ,IsDeleted + ,RequestMethod + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,TransactionId + ,HistoryTransactionId + ,NULL + ,NULL + FROM dbo.ResourceTbl + WHERE IsHistory = 0 +GO CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT AS BEGIN @@ -1871,6 +1926,239 @@ BEGIN CATCH THROW END CATCH GO +CREATE OR ALTER PROCEDURE dbo.tmp_MoveResources @ResourceTypeId smallint, @SurrogateId bigint, @CurrentMaxSurrogateId bigint, @LastProcessed varchar(100) +AS +set nocount on +DECLARE @Process varchar(100) = 'LakeSchemaUpgrade.MoveResources' + ,@Id varchar(100) = 'LakeSchemaUpgrade.MoveResources.LastProcessed.TypeId.SurrogateId' -- SELECT * FROM Parameters + ,@st datetime + ,@NewIdsCount int + ,@FirstIdInt bigint + ,@DummyTop bigint = 9223372036854775807 + +RetryResourceIdIntMapLogic: +BEGIN TRY + DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ExistingIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertIds AS TABLE (ResourceTypeId smallint NOT NULL, IdIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsReference AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @InsertedIdsResource AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) + DECLARE @ResourcesWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL + ,ResourceIdInt bigint NOT NULL + ,Version int NOT NULL + ,IsDeleted bit NOT NULL + ,IsHistory bit NOT NULL + ,RawResource varbinary(max) NULL + ,IsRawResourceMetaSet bit NOT NULL + ,RequestMethod varchar(10) NULL + ,SearchParamHash varchar(64) NULL + ,TransactionId bigint NULL + ,HistoryTransactionId bigint NULL + + PRIMARY KEY (ResourceTypeId, ResourceSurrogateId) + ,UNIQUE (ResourceTypeId, ResourceIdInt, Version) + ) + DECLARE @ReferenceSearchParamsWithIds AS TABLE + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL + + UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt) + ) + + -- reference search params Start --------------------------------------------------------------------------- + SET @st = getUTCdate() + INSERT INTO @InputIds + SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId + FROM dbo.ReferenceSearchParamTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + AND ReferenceResourceTypeId IS NOT NULL + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + INSERT INTO @ExistingIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, ResourceIdInt, A.ResourceId + FROM @InputIds A + JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsReference B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO @InsertedIdsReference + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + INSERT INTO @ReferenceSearchParamsWithIds + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) + FROM (SELECT TOP (@DummyTop) * + FROM dbo.ReferenceSearchParamTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + AND ReferenceResourceTypeId IS NOT NULL + ) A + LEFT OUTER JOIN @InsertedIdsReference B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId + LEFT OUTER JOIN @ExistingIdsReference C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId + OPTION (OPTIMIZE FOR (@DummyTop = 1)) + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='@ReferenceSearchParamsWithIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + + BEGIN TRANSACTION + + SET @st = getUTCdate() + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsReference + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Reference.ResourceIdIntMap',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + INSERT INTO dbo.ResourceReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt + FROM @ReferenceSearchParamsWithIds + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceReferenceSearchParams',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + INSERT INTO dbo.StringReferenceSearchParams + ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) + SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId + FROM dbo.ReferenceSearchParamTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + AND ReferenceResourceTypeId IS NULL + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='StringReferenceSearchParams',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + DELETE FROM dbo.ReferenceSearchParamTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st + + COMMIT TRANSACTION + -- reference search params End --------------------------------------------------------------------------- + + -- resources Start --------------------------------------------------------------------------- + SET @st = getUTCdate() + DELETE FROM @InputIds + INSERT INTO @InputIds + SELECT @ResourceTypeId, ResourceId + FROM (SELECT ResourceId + FROM dbo.ResourceTbl WITH (INDEX = 1) + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + ) A + GROUP BY ResourceId + OPTION (MAXDOP 1) + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceTbl.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + INSERT INTO @ExistingIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), A.ResourceId + FROM @InputIds A + LEFT OUTER JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @InsertedIdsReference C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + WHERE C.ResourceIdInt IS NOT NULL OR B.ResourceIdInt IS NOT NULL + + DELETE FROM @InsertIds + INSERT INTO @InsertIds + ( ResourceTypeId, IdIndex, ResourceId ) + SELECT ResourceTypeId, row_number() OVER (ORDER BY ResourceTypeId, ResourceId) - 1, ResourceId + FROM @InputIds A + WHERE NOT EXISTS (SELECT * FROM @ExistingIdsResource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId) + + SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) + IF @NewIdsCount > 0 + BEGIN + EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT + + INSERT INTO @InsertedIdsResource + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, IdIndex + @FirstIdInt, ResourceId + FROM @InsertIds + END + + INSERT INTO @ResourcesWithIds + ( ResourceTypeId, ResourceId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) + SELECT A.ResourceTypeId, A.ResourceId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId + FROM dbo.ResourceTbl A + LEFT OUTER JOIN @InsertedIdsResource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + LEFT OUTER JOIN @ExistingIdsResource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId + WHERE A.ResourceTypeId = @ResourceTypeId + AND A.ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='@ResourcesWithIds',@Action='Insert',@Rows=@@rowcount,@Start=@st + + BEGIN TRANSACTION + + SET @st = getUTCdate() + DELETE FROM dbo.ResourceTbl + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + INSERT INTO dbo.ResourceIdIntMap + ( ResourceTypeId, ResourceIdInt, ResourceId ) + SELECT ResourceTypeId, ResourceIdInt, ResourceId + FROM @InsertedIdsResource + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource.ResourceIdIntMap',@Action='Insert',@Rows=@@rowcount,@Start=@st + + SET @st = getUTCdate() + INSERT INTO dbo.Resource + ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId ) + SELECT ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId + FROM @ResourcesWithIds + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Insert',@Rows=@@rowcount,@Start=@st + + UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id + + COMMIT TRANSACTION + -- resources End --------------------------------------------------------------------------- +END TRY +BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + + EXECUTE dbo.LogEvent @Process=@Process,@Mode=@LastProcessed,@Status='Error',@Start=@st + + IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation + OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + BEGIN + DELETE FROM @ResourcesWithIds + DELETE FROM @ReferenceSearchParamsWithIds + DELETE FROM @InputIds + DELETE FROM @InsertIds + DELETE FROM @InsertedIdsReference + DELETE FROM @ExistingIdsReference + DELETE FROM @InsertedIdsResource + DELETE FROM @ExistingIdsResource + + GOTO RetryResourceIdIntMapLogic + END + ELSE + THROW +END CATCH +GO -- Move data -- ROLLBACK TRANSACTION set nocount on @@ -1904,24 +2192,13 @@ DECLARE @Process varchar(100) = 'LakeSchemaUpgrade.MoveResources' ,@RowsToProcess int ,@ProcessedResources int ,@ReportDate datetime = getUTCdate() - ,@DummyTop bigint = 9223372036854775807 ,@Rows int ,@CurrentMaxSurrogateId bigint ,@LastProcessed varchar(100) ,@st datetime - ,@NewIdsCount int - ,@Count int - ,@FirstIdInt bigint - ,@RT smallint INSERT INTO dbo.Parameters (Id, Char) SELECT @Process, 'LogEvent' -DECLARE @RTs AS TABLE (ResourceTypeId smallint NOT NULL PRIMARY KEY) -DECLARE @InputIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) -DECLARE @ExistingIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) -DECLARE @InsertIds AS TABLE (ResourceIndex int NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL) -DECLARE @InsertedIds AS TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL, ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS NOT NULL PRIMARY KEY (ResourceTypeId, ResourceId)) - BEGIN TRY EXECUTE dbo.LogEvent @Process=@Process,@Status='Start' @@ -1946,12 +2223,10 @@ BEGIN TRY SET @CurrentMaxSurrogateId = 0 WHILE @CurrentMaxSurrogateId IS NOT NULL BEGIN - BEGIN TRANSACTION - SET @CurrentMaxSurrogateId = NULL SELECT @CurrentMaxSurrogateId = max(ResourceSurrogateId), @RowsToProcess = count(*) FROM (SELECT TOP 5000 ResourceSurrogateId - FROM dbo.ResourceTbl WITH (HOLDLOCK, ROWLOCK) + FROM dbo.ResourceTbl WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @MaxSurrogateId ORDER BY ResourceSurrogateId ) A @@ -1960,172 +2235,7 @@ BEGIN TRY BEGIN SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@CurrentMaxSurrogateId) - RetryResourceIdIntMapInsert: - - DELETE FROM @InputIds - DELETE FROM @RTs - DELETE FROM @InsertedIds - DELETE FROM @ExistingIds - - BEGIN TRY - SET @st = getUTCdate() - INSERT INTO @InputIds SELECT DISTINCT ReferenceResourceTypeId, ReferenceResourceId - FROM dbo.ReferenceSearchParamTbl - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - AND ReferenceResourceTypeId IS NOT NULL - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st - - INSERT INTO @RTs SELECT DISTINCT ResourceTypeId FROM @InputIds - - -- Prepare id map for reference search params Start --------------------------------------------------------------------------- - SET @st = getUTCdate() - SET @Count = 0 - WHILE EXISTS (SELECT * FROM @RTs) - BEGIN - SET @RT = (SELECT TOP 1 ResourceTypeId FROM @RTs) - - INSERT INTO @ExistingIds - ( ResourceTypeId, ResourceIdInt, ResourceId ) - SELECT @RT, ResourceIdInt, A.ResourceId - FROM (SELECT * FROM @InputIds WHERE ResourceTypeId = @RT) A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId - - DELETE FROM @InsertIds - - INSERT INTO @InsertIds - ( ResourceIndex, ResourceId ) - SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId - FROM (SELECT ResourceId FROM @InputIds WHERE ResourceTypeId = @RT) A - WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @RT AND B.ResourceId = A.ResourceId) - - SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) - SET @Count += @NewIdsCount - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - - INSERT INTO dbo.ResourceIdIntMap - ( ResourceTypeId, ResourceIdInt, ResourceId ) - OUTPUT @RT, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @RT, ResourceIndex + @FirstIdInt, ResourceId - FROM @InsertIds - END - - DELETE FROM @RTs WHERE ResourceTypeId = @RT - END - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParam.ResourceIdIntMap',@Action='Insert',@Rows=@Count,@Start=@st - - SET @st = getUTCdate() - INSERT INTO dbo.ResourceReferenceSearchParams - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceIdInt ) - SELECT A.ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt) - FROM (SELECT TOP (@DummyTop) * - FROM dbo.ReferenceSearchParamTbl - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - AND ReferenceResourceTypeId IS NOT NULL - ) A - LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ReferenceResourceTypeId AND B.ResourceId = A.ReferenceResourceId - LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ReferenceResourceTypeId AND C.ResourceId = A.ReferenceResourceId - OPTION (OPTIMIZE FOR (@DummyTop = 1)) - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceReferenceSearchParams',@Action='Insert',@Rows=@@rowcount,@Start=@st - - SET @st = getUTCdate() - INSERT INTO dbo.StringReferenceSearchParams - ( ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId ) - SELECT ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceId - FROM dbo.ReferenceSearchParamTbl - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - AND ReferenceResourceTypeId IS NULL - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='StringReferenceSearchParams',@Action='Insert',@Rows=@@rowcount,@Start=@st - - SET @st = getUTCdate() - DELETE FROM dbo.ReferenceSearchParamTbl - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st - -- Prepare id map for reference search params End --------------------------------------------------------------------------- - - DELETE FROM @InputIds - DELETE FROM @RTs - DELETE FROM @InsertedIds - DELETE FROM @ExistingIds - - SET @st = getUTCdate() - INSERT INTO @InputIds - SELECT @ResourceTypeId, ResourceId - FROM (SELECT ResourceId - FROM dbo.ResourceTbl WITH (INDEX = 1) - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - ) A - GROUP BY ResourceId - OPTION (MAXDOP 1) - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceTbl.@InputIds',@Action='Insert',@Rows=@@rowcount,@Start=@st - - SET @st = getUTCdate() - SET @Count = 0 - INSERT INTO @ExistingIds - ( ResourceTypeId, ResourceIdInt, ResourceId ) - SELECT @ResourceTypeId, ResourceIdInt, A.ResourceId - FROM @InputIds A - JOIN dbo.ResourceIdIntMap B ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceId = A.ResourceId - - DELETE FROM @InsertIds - - INSERT INTO @InsertIds - ( ResourceIndex, ResourceId ) - SELECT RowId = row_number() OVER (ORDER BY ResourceId) - 1, ResourceId - FROM @InputIds A - WHERE NOT EXISTS (SELECT * FROM @ExistingIds B WHERE B.ResourceTypeId = @ResourceTypeId AND B.ResourceId = A.ResourceId) - - SET @NewIdsCount = (SELECT count(*) FROM @InsertIds) - IF @NewIdsCount > 0 - BEGIN - EXECUTE dbo.AssignResourceIdInts @NewIdsCount, @FirstIdInt OUT - - INSERT INTO dbo.ResourceIdIntMap - ( ResourceTypeId, ResourceIdInt, ResourceId ) - OUTPUT @ResourceTypeId, inserted.ResourceIdInt, inserted.ResourceId INTO @InsertedIds - SELECT @ResourceTypeId, ResourceIndex + @FirstIdInt, ResourceId - FROM @InsertIds - SET @Count = @@rowcount - END - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource.ResourceIdIntMap',@Action='Insert',@Rows=@Count,@Start=@st - - SET @st = getUTCdate() - INSERT INTO dbo.Resource - ( ResourceTypeId, ResourceIdInt, Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, FileId, OffsetInFile ) - SELECT A.ResourceTypeId, isnull(C.ResourceIdInt,B.ResourceIdInt), Version, IsHistory, ResourceSurrogateId, IsDeleted, RequestMethod, RawResource, IsRawResourceMetaSet, SearchParamHash, NULL, NULL - FROM dbo.ResourceTbl A - LEFT OUTER JOIN @InsertedIds B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - LEFT OUTER JOIN @ExistingIds C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceId = A.ResourceId - WHERE A.ResourceTypeId = @ResourceTypeId - AND A.ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='Resource',@Action='Insert',@Rows=@@rowcount,@Start=@st - - SET @st = getUTCdate() - DELETE FROM dbo.ResourceTbl - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId - EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st - END TRY - BEGIN CATCH - EXECUTE dbo.LogEvent @Process=@Process,@Mode=@LastProcessed,@Status='Error',@Start=@st - - IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' - BEGIN - GOTO RetryResourceIdIntMapInsert - END - ELSE - THROW - END CATCH - - UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id - - COMMIT TRANSACTION + EXECUTE tmp_MoveResources @ResourceTypeId = @ResourceTypeId, @SurrogateId = @SurrogateId, @CurrentMaxSurrogateId = @CurrentMaxSurrogateId, @LastProcessed = @LastProcessed SET @SurrogateId = @CurrentMaxSurrogateId @@ -2140,7 +2250,6 @@ BEGIN TRY END ELSE BEGIN - COMMIT TRANSACTION SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@MaxSurrogateId) UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id END @@ -2157,8 +2266,6 @@ BEGIN TRY EXECUTE dbo.LogEvent @Process=@Process,@Status='End' END TRY BEGIN CATCH - IF @@trancount > 0 ROLLBACK TRANSACTION - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; THROW END CATCH @@ -3604,3 +3711,5 @@ GO GO --DROP TABLE IF EXISTS ReferenceSearchParamTbl -- TODO: Remove table after deployment GO +--DROP PROCEDURE IF EXISTS tmp_MoveResources -- TODO: Remove table after deployment +GO From e6c5268b10f8aede745029593a0a652667abfeb5 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sat, 21 Dec 2024 13:06:24 -0800 Subject: [PATCH 064/111] optimized stored procedure --- .../Features/Schema/Migrations/85.diff.sql | 95 +++++++++++ .../Features/Schema/Migrations/85.sql | 157 +++++++++++++----- .../GetResourcesByTypeAndSurrogateIdRange.sql | 57 +++++-- .../SqlServerSchemaUpgradeTests.cs | 2 +- 4 files changed, 252 insertions(+), 59 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 392992c979..01b696482e 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -590,6 +590,101 @@ BEGIN WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) END GO +ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 0, @IncludeDeleted bit = 0 +AS +set nocount on +DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' + ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') + +' S='+isnull(convert(varchar,@StartId),'NULL') + +' E='+isnull(convert(varchar,@EndId),'NULL') + +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') + +' HI='+isnull(convert(varchar,@IncludeHistory),'NULL') + +' DE'+isnull(convert(varchar,@IncludeDeleted),'NULL') + ,@st datetime = getUTCdate() + ,@DummyTop bigint = 9223372036854775807 + ,@Rows int + +BEGIN TRY + DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) + DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) + + SET TRANSACTION ISOLATION LEVEL SNAPSHOT + + BEGIN TRANSACTION + + IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 -- snapshot view + BEGIN + INSERT INTO @ResourceIds + SELECT DISTINCT ResourceId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1) + + IF @@rowcount > 0 + INSERT INTO @SurrogateIds + SELECT ResourceSurrogateId + FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) + FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) -- w/o hint access to Resource table is inefficient when many versions are present. Hint is ignored if Resource is a view. + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) + AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId + ) A + WHERE RowId = 1 + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + END + + IF @IncludeHistory = 0 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 -- cannot use OR @IncludeHistory = 1 because SQL does not eliminate tables in the view + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1) + ELSE -- @IncludeHistory = 1 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1) + + SET @Rows = @@rowcount + + COMMIT TRANSACTION + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + THROW +END CATCH +GO IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ReferenceSearchParam' AND type = 'u') BEGIN BEGIN TRANSACTION diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index 41659bff84..999400575a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -3197,12 +3197,14 @@ CREATE PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @GlobalEndId BIGINT=NULL, @IncludeHistory BIT=0, @IncludeDeleted BIT=0 AS SET NOCOUNT ON; -DECLARE @SP AS VARCHAR (100) = 'GetResourcesByTypeAndSurrogateIdRange', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' GE=' + isnull(CONVERT (VARCHAR, @GlobalEndId), 'NULL') + ' HI=' + isnull(CONVERT (VARCHAR, @IncludeHistory), 'NULL') + ' DE' + isnull(CONVERT (VARCHAR, @IncludeDeleted), 'NULL'), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807; +DECLARE @SP AS VARCHAR (100) = 'GetResourcesByTypeAndSurrogateIdRange', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' GE=' + isnull(CONVERT (VARCHAR, @GlobalEndId), 'NULL') + ' HI=' + isnull(CONVERT (VARCHAR, @IncludeHistory), 'NULL') + ' DE' + isnull(CONVERT (VARCHAR, @IncludeDeleted), 'NULL'), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807, @Rows AS INT; BEGIN TRY DECLARE @ResourceIds TABLE ( ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY); DECLARE @SurrogateIds TABLE ( MaxSurrogateId BIGINT PRIMARY KEY); + SET TRANSACTION ISOLATION LEVEL SNAPSHOT; + BEGIN TRANSACTION; IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 BEGIN @@ -3230,50 +3232,115 @@ BEGIN TRY AND ResourceSurrogateId BETWEEN @StartId AND @EndId OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)); END - SELECT ResourceTypeId, - ResourceId, - Version, - IsDeleted, - ResourceSurrogateId, - RequestMethod, - CONVERT (BIT, 1) AS IsMatch, - CONVERT (BIT, 0) AS IsPartial, - IsRawResourceMetaSet, - SearchParamHash, - RawResource, - FileId, - OffsetInFile - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND (IsHistory = 0 - OR @IncludeHistory = 1) - AND (IsDeleted = 0 - OR @IncludeDeleted = 1) - UNION ALL - SELECT ResourceTypeId, - ResourceId, - Version, - IsDeleted, - ResourceSurrogateId, - RequestMethod, - CONVERT (BIT, 1) AS IsMatch, - CONVERT (BIT, 0) AS IsPartial, - IsRawResourceMetaSet, - SearchParamHash, - RawResource, - FileId, - OffsetInFile - FROM @SurrogateIds - INNER JOIN - dbo.Resource - ON ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId = MaxSurrogateId - WHERE IsHistory = 1 - AND (IsDeleted = 0 - OR @IncludeDeleted = 1) - OPTION (MAXDOP 1); - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; + IF @IncludeHistory = 0 + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource, + FileId, + OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource, + FileId, + OffsetInFile + FROM @SurrogateIds + INNER JOIN + dbo.Resource + ON ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + ELSE + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource, + FileId, + OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource, + FileId, + OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, + ResourceId, + Version, + IsDeleted, + ResourceSurrogateId, + RequestMethod, + CONVERT (BIT, 1) AS IsMatch, + CONVERT (BIT, 0) AS IsPartial, + IsRawResourceMetaSet, + SearchParamHash, + RawResource, + FileId, + OffsetInFile + FROM @SurrogateIds + INNER JOIN + dbo.Resource + ON ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 + OR @IncludeDeleted = 1) + OPTION (MAXDOP 1); + SET @Rows = @@rowcount; + COMMIT TRANSACTION; + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; END TRY BEGIN CATCH IF error_number() = 1750 diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql index 57bf64bde7..4740d2b5d5 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql @@ -12,11 +12,16 @@ DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' +' DE'+isnull(convert(varchar,@IncludeDeleted),'NULL') ,@st datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 + ,@Rows int BEGIN TRY DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) + SET TRANSACTION ISOLATION LEVEL SNAPSHOT + + BEGIN TRANSACTION + IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 -- snapshot view BEGIN INSERT INTO @ResourceIds @@ -42,21 +47,47 @@ BEGIN TRY OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) END - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND (IsHistory = 0 OR @IncludeHistory = 1) - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM @SurrogateIds - JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId - WHERE IsHistory = 1 - AND (IsDeleted = 0 OR @IncludeDeleted = 1) + IF @IncludeHistory = 0 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 -- cannot use OR @IncludeHistory = 1 because SQL does not eliminate tables in the view + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1) + ELSE -- @IncludeHistory = 1 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) OPTION (MAXDOP 1) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount + SET @Rows = @@rowcount + + COMMIT TRANSACTION + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs index e45a5ee610..f99cd3b1ff 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs @@ -285,7 +285,7 @@ private async Task CompareDatabaseSchemas(string databaseName1, string d { //// Our home grown SQL schema generator does not understand that statements can be formatted differently but contain identical SQL //// Skipping some objects - var objectsToSkip = new[] { "GetResourceSearchParamStats", "MergeResourcesAdvanceTransactionVisibility", "DequeueJob", "DisableIndexes", "GetResourceVersions", "CleanupEventLog", "InitDefrag", "EnqueueJobs", "GetResourcesByTypeAndSurrogateIdRange", "GetResourceSurrogateIdRanges", "GetCommandsForRebuildIndexes", "GetIndexCommands", "SwitchPartitionsIn", "SwitchPartitionsOut" }.ToList(); + var objectsToSkip = new[] { "GetResourceSearchParamStats", "MergeResourcesAdvanceTransactionVisibility", "DequeueJob", "DisableIndexes", "GetResourceVersions", "CleanupEventLog", "InitDefrag", "EnqueueJobs", "GetResourceSurrogateIdRanges", "GetCommandsForRebuildIndexes", "GetIndexCommands", "SwitchPartitionsIn", "SwitchPartitionsOut" }.ToList(); objectsToSkip.Add("PartitionFunction_ResourceChangeData_Timestamp"); // definition is not predictable as it has start time component if (schemaDifference.SourceObject != null && objectsToSkip.Any(_ => schemaDifference.SourceObject.Name.ToString().Contains(_))) { From f5764a4e08440f5c3fd3314e531df8b23a48bb0f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 22 Dec 2024 10:07:31 -0800 Subject: [PATCH 065/111] export --- .../Features/Schema/Migrations/85.diff.sql | 253 +++++++++++------- .../Features/Schema/Migrations/85.sql | 69 ++--- .../GetResourcesByTypeAndSurrogateIdRange.sql | 48 ++-- 3 files changed, 192 insertions(+), 178 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 01b696482e..0698bc4946 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -590,101 +590,6 @@ BEGIN WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) END GO -ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 0, @IncludeDeleted bit = 0 -AS -set nocount on -DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' - ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') - +' S='+isnull(convert(varchar,@StartId),'NULL') - +' E='+isnull(convert(varchar,@EndId),'NULL') - +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') - +' HI='+isnull(convert(varchar,@IncludeHistory),'NULL') - +' DE'+isnull(convert(varchar,@IncludeDeleted),'NULL') - ,@st datetime = getUTCdate() - ,@DummyTop bigint = 9223372036854775807 - ,@Rows int - -BEGIN TRY - DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) - DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) - - SET TRANSACTION ISOLATION LEVEL SNAPSHOT - - BEGIN TRANSACTION - - IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 -- snapshot view - BEGIN - INSERT INTO @ResourceIds - SELECT DISTINCT ResourceId - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 1 - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - OPTION (MAXDOP 1) - - IF @@rowcount > 0 - INSERT INTO @SurrogateIds - SELECT ResourceSurrogateId - FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) - FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) -- w/o hint access to Resource table is inefficient when many versions are present. Hint is ignored if Resource is a view. - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) - AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId - ) A - WHERE RowId = 1 - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - END - - IF @IncludeHistory = 0 - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 0 -- cannot use OR @IncludeHistory = 1 because SQL does not eliminate tables in the view - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM @SurrogateIds - JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId - WHERE IsHistory = 1 - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - OPTION (MAXDOP 1) - ELSE -- @IncludeHistory = 1 - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 0 - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 1 - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM @SurrogateIds - JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId - WHERE IsHistory = 1 - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - OPTION (MAXDOP 1) - - SET @Rows = @@rowcount - - COMMIT TRANSACTION - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows -END TRY -BEGIN CATCH - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; - THROW -END CATCH -GO IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ReferenceSearchParam' AND type = 'u') BEGIN BEGIN TRANSACTION @@ -1720,6 +1625,85 @@ COMMIT TRANSACTION GO -- Special versions of procedures for data movement GO +ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 1, @IncludeDeleted bit = 1 +AS +set nocount on +DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' + ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') + +' S='+isnull(convert(varchar,@StartId),'NULL') + +' E='+isnull(convert(varchar,@EndId),'NULL') + +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') + +' HI='+isnull(convert(varchar,@IncludeHistory),'NULL') + +' DE='+isnull(convert(varchar,@IncludeDeleted),'NULL') + ,@st datetime = getUTCdate() + ,@DummyTop bigint = 9223372036854775807 + ,@Rows int + +BEGIN TRY + DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) + DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) + + IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 -- snapshot view + BEGIN + INSERT INTO @ResourceIds + SELECT DISTINCT ResourceId + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1) + + IF @@rowcount > 0 + INSERT INTO @SurrogateIds + SELECT ResourceSurrogateId + FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) + AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId + ) A + WHERE RowId = 1 + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + END + + IF @IncludeHistory = 0 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1, LOOP JOIN) + ELSE -- @IncludeHistory = 1 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1, LOOP JOIN) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + THROW +END CATCH +GO ALTER PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId bigint, @AffectedRows int = NULL OUT AS set nocount on @@ -3802,6 +3786,85 @@ BEGIN CATCH THROW END CATCH GO +ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 1, @IncludeDeleted bit = 1 +AS +set nocount on +DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' + ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') + +' S='+isnull(convert(varchar,@StartId),'NULL') + +' E='+isnull(convert(varchar,@EndId),'NULL') + +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') + +' HI='+isnull(convert(varchar,@IncludeHistory),'NULL') + +' DE='+isnull(convert(varchar,@IncludeDeleted),'NULL') + ,@st datetime = getUTCdate() + ,@DummyTop bigint = 9223372036854775807 + ,@Rows int + +BEGIN TRY + DECLARE @ResourceIdInts TABLE (ResourceIdInt bigint PRIMARY KEY) + DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) + + IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 -- snapshot view + BEGIN + INSERT INTO @ResourceIdInts + SELECT DISTINCT ResourceIdInt + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1) + + IF @@rowcount > 0 + INSERT INTO @SurrogateIds + SELECT ResourceSurrogateId + FROM (SELECT ResourceIdInt, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceIdInt ORDER BY ResourceSurrogateId DESC) + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceIdInt IN (SELECT TOP (@DummyTop) ResourceIdInt FROM @ResourceIdInts) + AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId + ) A + WHERE RowId = 1 + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + END + + IF @IncludeHistory = 0 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND IsHistory = 0 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1, LOOP JOIN) + ELSE -- @IncludeHistory = 1 + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM dbo.Resource + WHERE ResourceTypeId = @ResourceTypeId + AND ResourceSurrogateId BETWEEN @StartId AND @EndId + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + UNION ALL + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + FROM @SurrogateIds + JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId + WHERE IsHistory = 1 + AND (IsDeleted = 0 OR @IncludeDeleted = 1) + OPTION (MAXDOP 1, LOOP JOIN) + + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + THROW +END CATCH +GO --DROP TABLE IF EXISTS ResourceTbl -- TODO: Remove table after deployment GO --DROP TABLE IF EXISTS ReferenceSearchParamTbl -- TODO: Remove table after deployment diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index 999400575a..ab3d23ce18 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -3194,22 +3194,20 @@ END CATCH GO CREATE PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange -@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @GlobalEndId BIGINT=NULL, @IncludeHistory BIT=0, @IncludeDeleted BIT=0 +@ResourceTypeId SMALLINT, @StartId BIGINT, @EndId BIGINT, @GlobalEndId BIGINT=NULL, @IncludeHistory BIT=1, @IncludeDeleted BIT=1 AS SET NOCOUNT ON; -DECLARE @SP AS VARCHAR (100) = 'GetResourcesByTypeAndSurrogateIdRange', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' GE=' + isnull(CONVERT (VARCHAR, @GlobalEndId), 'NULL') + ' HI=' + isnull(CONVERT (VARCHAR, @IncludeHistory), 'NULL') + ' DE' + isnull(CONVERT (VARCHAR, @IncludeDeleted), 'NULL'), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807, @Rows AS INT; +DECLARE @SP AS VARCHAR (100) = 'GetResourcesByTypeAndSurrogateIdRange', @Mode AS VARCHAR (100) = 'RT=' + isnull(CONVERT (VARCHAR, @ResourceTypeId), 'NULL') + ' S=' + isnull(CONVERT (VARCHAR, @StartId), 'NULL') + ' E=' + isnull(CONVERT (VARCHAR, @EndId), 'NULL') + ' GE=' + isnull(CONVERT (VARCHAR, @GlobalEndId), 'NULL') + ' HI=' + isnull(CONVERT (VARCHAR, @IncludeHistory), 'NULL') + ' DE=' + isnull(CONVERT (VARCHAR, @IncludeDeleted), 'NULL'), @st AS DATETIME = getUTCdate(), @DummyTop AS BIGINT = 9223372036854775807, @Rows AS INT; BEGIN TRY - DECLARE @ResourceIds TABLE ( - ResourceId VARCHAR (64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY); + DECLARE @ResourceIdInts TABLE ( + ResourceIdInt BIGINT PRIMARY KEY); DECLARE @SurrogateIds TABLE ( MaxSurrogateId BIGINT PRIMARY KEY); - SET TRANSACTION ISOLATION LEVEL SNAPSHOT; - BEGIN TRANSACTION; IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 BEGIN - INSERT INTO @ResourceIds - SELECT DISTINCT ResourceId + INSERT INTO @ResourceIdInts + SELECT DISTINCT ResourceIdInt FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId @@ -3220,13 +3218,13 @@ BEGIN TRY IF @@rowcount > 0 INSERT INTO @SurrogateIds SELECT ResourceSurrogateId - FROM (SELECT ResourceId, + FROM (SELECT ResourceIdInt, ResourceSurrogateId, - row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) AS RowId - FROM dbo.Resource WITH (INDEX (IX_Resource_ResourceTypeId_ResourceId_Version)) + row_number() OVER (PARTITION BY ResourceIdInt ORDER BY ResourceSurrogateId DESC) AS RowId + FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId - FROM @ResourceIds) + AND ResourceIdInt IN (SELECT TOP (@DummyTop) ResourceIdInt + FROM @ResourceIdInts) AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId) AS A WHERE RowId = 1 AND ResourceSurrogateId BETWEEN @StartId AND @EndId @@ -3243,9 +3241,7 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource, - FileId, - OffsetInFile + RawResource FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId @@ -3263,9 +3259,7 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource, - FileId, - OffsetInFile + RawResource FROM @SurrogateIds INNER JOIN dbo.Resource @@ -3274,7 +3268,7 @@ BEGIN TRY WHERE IsHistory = 1 AND (IsDeleted = 0 OR @IncludeDeleted = 1) - OPTION (MAXDOP 1); + OPTION (MAXDOP 1, LOOP JOIN); ELSE SELECT ResourceTypeId, ResourceId, @@ -3286,13 +3280,10 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource, - FileId, - OffsetInFile + RawResource FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 0 AND (IsDeleted = 0 OR @IncludeDeleted = 1) UNION ALL @@ -3306,29 +3297,7 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource, - FileId, - OffsetInFile - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 1 - AND (IsDeleted = 0 - OR @IncludeDeleted = 1) - UNION ALL - SELECT ResourceTypeId, - ResourceId, - Version, - IsDeleted, - ResourceSurrogateId, - RequestMethod, - CONVERT (BIT, 1) AS IsMatch, - CONVERT (BIT, 0) AS IsPartial, - IsRawResourceMetaSet, - SearchParamHash, - RawResource, - FileId, - OffsetInFile + RawResource FROM @SurrogateIds INNER JOIN dbo.Resource @@ -3337,10 +3306,8 @@ BEGIN TRY WHERE IsHistory = 1 AND (IsDeleted = 0 OR @IncludeDeleted = 1) - OPTION (MAXDOP 1); - SET @Rows = @@rowcount; - COMMIT TRANSACTION; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @Rows; + OPTION (MAXDOP 1, LOOP JOIN); + EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st, @Rows = @@rowcount; END TRY BEGIN CATCH IF error_number() = 1750 diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql index 4740d2b5d5..06d6bf4bfa 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql @@ -1,6 +1,6 @@ --DROP PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange GO -CREATE PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 0, @IncludeDeleted bit = 0 +CREATE PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 1, @IncludeDeleted bit = 1 AS set nocount on DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' @@ -9,23 +9,19 @@ DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' +' E='+isnull(convert(varchar,@EndId),'NULL') +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') +' HI='+isnull(convert(varchar,@IncludeHistory),'NULL') - +' DE'+isnull(convert(varchar,@IncludeDeleted),'NULL') + +' DE='+isnull(convert(varchar,@IncludeDeleted),'NULL') ,@st datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 ,@Rows int BEGIN TRY - DECLARE @ResourceIds TABLE (ResourceId varchar(64) COLLATE Latin1_General_100_CS_AS PRIMARY KEY) + DECLARE @ResourceIdInts TABLE (ResourceIdInt bigint PRIMARY KEY) DECLARE @SurrogateIds TABLE (MaxSurrogateId bigint PRIMARY KEY) - SET TRANSACTION ISOLATION LEVEL SNAPSHOT - - BEGIN TRANSACTION - IF @GlobalEndId IS NOT NULL AND @IncludeHistory = 0 -- snapshot view BEGIN - INSERT INTO @ResourceIds - SELECT DISTINCT ResourceId + INSERT INTO @ResourceIdInts + SELECT DISTINCT ResourceIdInt FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId @@ -36,10 +32,10 @@ BEGIN TRY IF @@rowcount > 0 INSERT INTO @SurrogateIds SELECT ResourceSurrogateId - FROM (SELECT ResourceId, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceId ORDER BY ResourceSurrogateId DESC) - FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) -- w/o hint access to Resource table is inefficient when many versions are present. Hint is ignored if Resource is a view. + FROM (SELECT ResourceIdInt, ResourceSurrogateId, RowId = row_number() OVER (PARTITION BY ResourceIdInt ORDER BY ResourceSurrogateId DESC) + FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId - AND ResourceId IN (SELECT TOP (@DummyTop) ResourceId FROM @ResourceIds) + AND ResourceIdInt IN (SELECT TOP (@DummyTop) ResourceIdInt FROM @ResourceIdInts) AND ResourceSurrogateId BETWEEN @StartId AND @GlobalEndId ) A WHERE RowId = 1 @@ -48,46 +44,34 @@ BEGIN TRY END IF @IncludeHistory = 0 - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 0 -- cannot use OR @IncludeHistory = 1 because SQL does not eliminate tables in the view + AND IsHistory = 0 AND (IsDeleted = 0 OR @IncludeDeleted = 1) UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 AND (IsDeleted = 0 OR @IncludeDeleted = 1) - OPTION (MAXDOP 1) + OPTION (MAXDOP 1, LOOP JOIN) ELSE -- @IncludeHistory = 1 - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile - FROM dbo.Resource - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 0 - AND (IsDeleted = 0 OR @IncludeDeleted = 1) - UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId - AND IsHistory = 1 AND (IsDeleted = 0 OR @IncludeDeleted = 1) UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 AND (IsDeleted = 0 OR @IncludeDeleted = 1) - OPTION (MAXDOP 1) - - SET @Rows = @@rowcount - - COMMIT TRANSACTION + OPTION (MAXDOP 1, LOOP JOIN) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@Rows + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. From cde091892f698a46c1c209671fcb56fefd516079 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 22 Dec 2024 21:40:54 -0800 Subject: [PATCH 066/111] Simple sort value logic --- .../Visitors/QueryGenerators/SqlQueryGenerator.cs | 2 +- .../Features/Search/SqlServerSearchService.cs | 12 +++++++----- 2 files changed, 8 insertions(+), 6 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 61695e6567..dcb1a7e073 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -1364,7 +1364,7 @@ private static bool IsPrimaryKeySort(SearchOptions searchOptions) return searchOptions.Sort.All(s => s.searchParameterInfo.Name is SearchParameterNames.ResourceType or SearchParameterNames.LastUpdated); } - private bool IsSortValueNeeded(SearchOptions context) + internal bool IsSortValueNeeded(SearchOptions context) { if (context.Sort.Count == 0) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 5b61d12661..b9e110bdf9 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -68,7 +68,6 @@ internal class SqlServerSearchService : SearchService private readonly SchemaInformation _schemaInformation; private readonly ICompressedRawResourceConverter _compressedRawResourceConverter; private readonly RequestContextAccessor _requestContextAccessor; - private const int _defaultNumberOfColumnsReadFromResult = 11; private readonly SearchParameterInfo _fakeLastUpdate = new SearchParameterInfo(SearchParameterNames.LastUpdated, SearchParameterNames.LastUpdated); private readonly IParameterStore _parameterStore; private static ResourceSearchParamStats _resourceSearchParamStats; @@ -336,6 +335,8 @@ await _sqlRetryService.ExecuteSql( using (SqlCommand sqlCommand = connection.CreateCommand()) // WARNING, this code will not set sqlCommand.Transaction. Sql transactions via C#/.NET are not supported in this method. { sqlCommand.CommandTimeout = (int)_sqlServerDataStoreConfiguration.CommandTimeout.TotalSeconds; + var isSortValueNeeded = false; + var didWeReadSortValue = false; var exportTimeTravel = clonedSearchOptions.QueryHints != null && ContainsGlobalEndSurrogateId(clonedSearchOptions); if (exportTimeTravel) @@ -358,6 +359,7 @@ await _sqlRetryService.ExecuteSql( sqlException); expression.AcceptVisitor(queryGenerator, clonedSearchOptions); + isSortValueNeeded = queryGenerator.IsSortValueNeeded(clonedSearchOptions); SqlCommandSimplifier.RemoveRedundantParameters(stringBuilder, sqlCommand.Parameters, _logger); @@ -477,12 +479,12 @@ await _sqlRetryService.ExecuteSql( newContinuationType = resourceTypeId; newContinuationId = resourceSurrogateId; - // For normal queries, we select _defaultNumberOfColumnsReadFromResult number of columns. - // If we have more, that means we have an extra column tracking sort value. + // If sort value needed, that means we have an extra column tracking sort value. // Keep track of sort value if this is the last row. - if (matchCount == clonedSearchOptions.MaxItemCount - 1 && reader.FieldCount > _defaultNumberOfColumnsReadFromResult) + if (matchCount == clonedSearchOptions.MaxItemCount - 1 && isSortValueNeeded) { var tempSortValue = reader.GetValue(SortValueColumnName); + didWeReadSortValue = true; if ((tempSortValue as DateTime?) != null) { sortValue = (tempSortValue as DateTime?).Value.ToString("o"); @@ -547,7 +549,7 @@ await _sqlRetryService.ExecuteSql( clonedSearchOptions.Sort[0].searchParameterInfo.Code != KnownQueryParameterNames.LastUpdated) { // If there is an extra column for sort value, we know we have searched for sort values. If no results were returned, we don't know if we have searched for sort values so we need to assume we did so we run the second phase. - sqlSearchOptions.DidWeSearchForSortValue = numberOfColumnsRead > _defaultNumberOfColumnsReadFromResult; + sqlSearchOptions.DidWeSearchForSortValue = didWeReadSortValue; } // This value is set inside the SortRewriter. If it is set, we need to pass From 584083472bddc337c92637ac3f1ec99e88727f4d Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 23 Dec 2024 07:54:09 -0800 Subject: [PATCH 067/111] plus --- .../Features/Search/SqlServerSearchService.cs | 7 +------ 1 file changed, 1 insertion(+), 6 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index b9e110bdf9..c3deb5e0d3 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -336,7 +336,6 @@ await _sqlRetryService.ExecuteSql( { sqlCommand.CommandTimeout = (int)_sqlServerDataStoreConfiguration.CommandTimeout.TotalSeconds; var isSortValueNeeded = false; - var didWeReadSortValue = false; var exportTimeTravel = clonedSearchOptions.QueryHints != null && ContainsGlobalEndSurrogateId(clonedSearchOptions); if (exportTimeTravel) @@ -417,7 +416,6 @@ await _sqlRetryService.ExecuteSql( string sortValue = null; var isResultPartial = false; - int numberOfColumnsRead = 0; while (await reader.ReadAsync(cancellationToken)) { @@ -441,8 +439,6 @@ await _sqlRetryService.ExecuteSql( continue; } - numberOfColumnsRead = reader.FieldCount; - // If we get to this point, we know there are more results so we need a continuation token // Additionally, this resource shouldn't be included in the results if (matchCount >= clonedSearchOptions.MaxItemCount && isMatch) @@ -484,7 +480,6 @@ await _sqlRetryService.ExecuteSql( if (matchCount == clonedSearchOptions.MaxItemCount - 1 && isSortValueNeeded) { var tempSortValue = reader.GetValue(SortValueColumnName); - didWeReadSortValue = true; if ((tempSortValue as DateTime?) != null) { sortValue = (tempSortValue as DateTime?).Value.ToString("o"); @@ -549,7 +544,7 @@ await _sqlRetryService.ExecuteSql( clonedSearchOptions.Sort[0].searchParameterInfo.Code != KnownQueryParameterNames.LastUpdated) { // If there is an extra column for sort value, we know we have searched for sort values. If no results were returned, we don't know if we have searched for sort values so we need to assume we did so we run the second phase. - sqlSearchOptions.DidWeSearchForSortValue = didWeReadSortValue; + sqlSearchOptions.DidWeSearchForSortValue = isSortValueNeeded; } // This value is set inside the SortRewriter. If it is set, we need to pass From 22174f7d8bd76edd47cd89a2afcc0d6e8d59c59b Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 23 Dec 2024 11:31:22 -0800 Subject: [PATCH 068/111] 11->12 plus comments --- .../Features/Search/SqlServerSearchService.cs | 6 ++++-- .../Features/Storage/SqlStoreClient.cs | 2 +- 2 files changed, 5 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index ba54b6be9c..7c9a45e4d7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -848,8 +848,10 @@ private void ReadWrapper( isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 8); searchParameterHash = reader.Read(VLatest.Resource.SearchParamHash, 9); rawResourceSqlBytes = reader.GetSqlBytes(10); - fileId = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.FileId, 11) : null; - offsetInFile = reader.FieldCount > 11 ? reader.Read(VLatest.Resource.OffsetInFile, 12) : null; + //// TODO: Remove field count check when Lake schema is deployed + //// Number of fields in old schema is either 11 or 12 (12th is sort value). In new schema, it is either 13 or 14. + fileId = reader.FieldCount > 12 ? reader.Read(VLatest.Resource.FileId, 11) : null; + offsetInFile = reader.FieldCount > 12 ? reader.Read(VLatest.Resource.OffsetInFile, 12) : null; isInvisible = false; if (!rawResourceSqlBytes.IsNull) { diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 97b9e2fd2c..0b694d0ae2 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -180,7 +180,7 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re var isDeleted = reader.Read(VLatest.Resource.IsDeleted, 4); var isHistory = reader.Read(VLatest.Resource.IsHistory, 5); var bytes = reader.GetSqlBytes(6); - var fileId = reader.FieldCount > 10 ? reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9) : null; // TODO: Remove field count check after deployment + var fileId = reader.FieldCount > 10 ? reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9) : null; // TODO: Remove field count check after Lake schema deployment var offsetInFile = reader.FieldCount > 10 ? reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10) : null; var rawResource = ReadRawResource(bytes, decompress, fileId, offsetInFile); var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); From ff6958569e6ab9f6a1d1b02ee9ac5fe8666c330e Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 23 Dec 2024 20:00:32 -0800 Subject: [PATCH 069/111] null check --- .../Features/Storage/SqlStoreClient.cs | 5 +++++ 1 file changed, 5 insertions(+) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 0b694d0ae2..048f17481d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -99,6 +99,11 @@ public static Lazy GetRawResourceFromAdls(long fileId, int offsetInFile) return new Lazy(() => { var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(fileId); + if (SqlAdlsCient.Container == null) + { + throw new InvalidOperationException("ADLS container is null."); + } + using var reader = new StreamReader(SqlAdlsCient.Container.GetBlobClient(blobName).OpenRead(offsetInFile)); var line = reader.ReadLine(); return line; From a8b7de2da218ee602305a429204e6cc58eaab379 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 24 Dec 2024 08:35:38 -0800 Subject: [PATCH 070/111] adls message --- .../Features/Storage/SqlAdlsCient.cs | 2 ++ 1 file changed, 2 insertions(+) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs index e40783ac26..cb3728f3b5 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs @@ -58,6 +58,8 @@ public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) _adlsContainer = GetContainer(); } + sqlRetryService.TryLogEvent("AdlsClient", "Warn", $"ADLS client is set with {(_adlsContainer == null ? "NULL" : _adlsContainerName)} container.", null, CancellationToken.None).Wait(); + _adlsIsSet = true; } } From 53d5930a1dbbc5ae0f06551ceff4430af1712c11 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 24 Dec 2024 08:39:48 -0800 Subject: [PATCH 071/111] message --- .../Features/Storage/SqlAdlsCient.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs index cb3728f3b5..84df7852bc 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs @@ -58,7 +58,7 @@ public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) _adlsContainer = GetContainer(); } - sqlRetryService.TryLogEvent("AdlsClient", "Warn", $"ADLS client is set with {(_adlsContainer == null ? "NULL" : _adlsContainerName)} container.", null, CancellationToken.None).Wait(); + sqlRetryService.TryLogEvent("SqlAdlsClient", "Warn", $"Storage container is set to {(_adlsContainer == null ? "NULL" : _adlsContainerName)}", null, CancellationToken.None).Wait(); _adlsIsSet = true; } From ccdc3e5e71ced11fbe4f5b855c4556f73360883c Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 24 Dec 2024 08:51:17 -0800 Subject: [PATCH 072/111] log --- .../Features/Storage/SqlAdlsCient.cs | 1 + 1 file changed, 1 insertion(+) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs index 84df7852bc..db57bfa1e0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs @@ -58,6 +58,7 @@ public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) _adlsContainer = GetContainer(); } + logger.LogInformation($"Storage container is set to {(_adlsContainer == null ? "NULL" : _adlsContainerName)}"); sqlRetryService.TryLogEvent("SqlAdlsClient", "Warn", $"Storage container is set to {(_adlsContainer == null ? "NULL" : _adlsContainerName)}", null, CancellationToken.None).Wait(); _adlsIsSet = true; From 8b35734f9683823ee04cce17b94e10c8fedd2524 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 24 Dec 2024 17:12:25 -0800 Subject: [PATCH 073/111] 2 columns back --- .../Features/Schema/Migrations/85.sql | 16 ++++++++++++---- .../GetResourcesByTypeAndSurrogateIdRange.sql | 8 ++++---- 2 files changed, 16 insertions(+), 8 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index ab3d23ce18..f2d16d9277 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -3241,7 +3241,9 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource + RawResource, + FileId, + OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId @@ -3259,7 +3261,9 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource + RawResource, + FileId, + OffsetInFile FROM @SurrogateIds INNER JOIN dbo.Resource @@ -3280,7 +3284,9 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource + RawResource, + FileId, + OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId @@ -3297,7 +3303,9 @@ BEGIN TRY CONVERT (BIT, 0) AS IsPartial, IsRawResourceMetaSet, SearchParamHash, - RawResource + RawResource, + FileId, + OffsetInFile FROM @SurrogateIds INNER JOIN dbo.Resource diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql index 06d6bf4bfa..f2853edc60 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetResourcesByTypeAndSurrogateIdRange.sql @@ -44,27 +44,27 @@ BEGIN TRY END IF @IncludeHistory = 0 - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND IsHistory = 0 AND (IsDeleted = 0 OR @IncludeDeleted = 1) UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 AND (IsDeleted = 0 OR @IncludeDeleted = 1) OPTION (MAXDOP 1, LOOP JOIN) ELSE -- @IncludeHistory = 1 - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile FROM dbo.Resource WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId AND (IsDeleted = 0 OR @IncludeDeleted = 1) UNION ALL - SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource--, FileId, OffsetInFile + SELECT ResourceTypeId, ResourceId, Version, IsDeleted, ResourceSurrogateId, RequestMethod, IsMatch = convert(bit,1), IsPartial = convert(bit,0), IsRawResourceMetaSet, SearchParamHash, RawResource, FileId, OffsetInFile FROM @SurrogateIds JOIN dbo.Resource ON ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId = MaxSurrogateId WHERE IsHistory = 1 From b17416ba8f4b979c6a4aed2648db0d6c663cf3f4 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 26 Dec 2024 14:35:27 -0800 Subject: [PATCH 074/111] exporter with file/blob API --- Directory.Packages.props | 3 +- tools/Exporter/App.config | 7 +- tools/Exporter/Exporter.csproj | 4 +- tools/Exporter/Program.cs | 320 +++++++++++++++--- tools/Exporter/Properties/launchSettings.json | 8 + tools/Exporter/SqlParamaterStringExtension.cs | 4 +- tools/Exporter/SqlService.cs | 34 +- 7 files changed, 320 insertions(+), 60 deletions(-) create mode 100644 tools/Exporter/Properties/launchSettings.json diff --git a/Directory.Packages.props b/Directory.Packages.props index f4e78d27e8..584100c9cc 100644 --- a/Directory.Packages.props +++ b/Directory.Packages.props @@ -6,6 +6,7 @@ + @@ -125,4 +126,4 @@ - + \ No newline at end of file diff --git a/tools/Exporter/App.config b/tools/Exporter/App.config index f653b9471c..5f6e6af990 100644 --- a/tools/Exporter/App.config +++ b/tools/Exporter/App.config @@ -1,11 +1,12 @@  - + - - + + + diff --git a/tools/Exporter/Exporter.csproj b/tools/Exporter/Exporter.csproj index 99a406015a..3ccc41ca90 100644 --- a/tools/Exporter/Exporter.csproj +++ b/tools/Exporter/Exporter.csproj @@ -6,6 +6,7 @@ Microsoft.Health.Internal.Fhir.Exporter enable true + net6.0 @@ -13,9 +14,8 @@ - + - diff --git a/tools/Exporter/Program.cs b/tools/Exporter/Program.cs index 58f8f02c66..4193da3dcc 100644 --- a/tools/Exporter/Program.cs +++ b/tools/Exporter/Program.cs @@ -6,27 +6,31 @@ using System; using System.Collections.Generic; using System.Configuration; -using System.Data.SqlClient; using System.Diagnostics; using System.IO; using System.Linq; +using System.Security.Cryptography; +using System.Text; using System.Threading; using System.Threading.Tasks; +using Azure.Identity; using Azure.Storage.Blobs; using Azure.Storage.Blobs.Specialized; -using Microsoft.Health.Fhir.SqlServer.Features; -using Microsoft.Health.Fhir.Store.Export; +using Azure.Storage.Files.DataLake; +using Microsoft.AspNetCore.Components.Forms; +using Microsoft.Data.SqlClient; using Microsoft.Health.Fhir.Store.Utils; -using Microsoft.Health.Internal.Fhir.Sql; +using Microsoft.Health.Internal.Fhir.Exporter; +using Task = System.Threading.Tasks.Task; -namespace Microsoft.Health.Internal.Fhir.Exporter +namespace Microsoft.Health.Fhir.Store.Export { public static class Program { - private static readonly string _connectionString = ConfigurationManager.ConnectionStrings["Database"].ConnectionString; - private static readonly SqlService Store = new SqlService(_connectionString); - private static readonly string BlobConnectionString = ConfigurationManager.AppSettings["BlobConnectionString"]; - private static readonly string BlobContainerName = ConfigurationManager.AppSettings["BlobContainerName"]; + private static readonly string ConnectionString = ConfigurationManager.ConnectionStrings["Database"].ConnectionString; + private static readonly string AdlsUri = ConfigurationManager.AppSettings["AdlsUri"]; + private static readonly string AdlsUAMI = ConfigurationManager.AppSettings["AdlsUAMI"]; + private static readonly string AdlsContainerName = ConfigurationManager.AppSettings["AdlsContainerName"]; private static readonly int Threads = int.Parse(ConfigurationManager.AppSettings["Threads"]); private static readonly string ResourceType = ConfigurationManager.AppSettings["ResourceType"]; private static readonly int UnitSize = int.Parse(ConfigurationManager.AppSettings["UnitSize"]); @@ -38,6 +42,7 @@ public static class Program private static readonly int ReportingPeriodSec = int.Parse(ConfigurationManager.AppSettings["ReportingPeriodSec"]); private static readonly DateTime StartDate = DateTime.Parse(ConfigurationManager.AppSettings["StartDate"]); private static readonly DateTime EndDate = DateTime.Parse(ConfigurationManager.AppSettings["EndDate"]); + private static readonly SqlService Source = new SqlService(ConnectionString); private static bool stop = false; private static long _resourcesTotal = 0L; private static Stopwatch _swReport = Stopwatch.StartNew(); @@ -46,33 +51,253 @@ public static class Program private static Stopwatch _database = new Stopwatch(); private static Stopwatch _unzip = new Stopwatch(); private static Stopwatch _blob = new Stopwatch(); + private static BlobContainerClient _blobContainer; + private static DataLakeFileSystemClient _fileSystem; public static void Main(string[] args) { - Console.WriteLine($"Source=[{_connectionString}]"); - if (args.Length > 0 && args[0] == "noqueue") + if (args.Length > 0 && args[0] == "random") { - ExportNoQueue(); + var count = args.Length > 1 ? int.Parse(args[1]) : 100; + _blobContainer = GetContainer(AdlsUri, AdlsUAMI, AdlsContainerName); + _fileSystem = new DataLakeFileSystemClient(new Uri($"{AdlsUri}/{AdlsContainerName}"), string.IsNullOrEmpty(AdlsUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(AdlsUAMI)); + try + { + _fileSystem.GetFileClient("blobName").OpenRead(); + } + catch + { + } + + var parall = args.Length > 2 ? int.Parse(args[2]) : 8; + + RandomReads(count, parall); + } + else if (args.Length == 0 || args[0] == "storage") + { + var count = args.Length > 1 ? int.Parse(args[1]) : 100; + var bufferKB = args.Length > 2 ? int.Parse(args[2]) : 20; + var parall = args.Length > 3 ? int.Parse(args[3]) : 1; + WriteAndReadAdls(count, bufferKB); + WriteAndReadBlob(count, bufferKB, parall); } else { - if (RebuildWorkQueue) + Console.WriteLine($"Source=[{Source.ShowConnectionString()}]"); + if (args.Length > 0 && args[0] == "noqueue") { - PopulateJobQueue(ResourceType, UnitSize); + ExportNoQueue(); } + else + { + if (RebuildWorkQueue) + { + PopulateJobQueue(ResourceType, UnitSize); + } + + Export(); + } + } + } + + public static void RandomReads(int count, int parall) + { + var maxId = LastUpdatedToResourceSurrogateId(DateTime.UtcNow); + var ranges = Source.GetSurrogateIdRanges(96, 0, maxId, 10000, 10000); + var refs = new List<(long FileId, int OffsetInFile)>(); + foreach (var range in ranges) + { + refs.AddRange(Source.GetRefs(96, range.StartId, range.EndId)); + } + + Console.WriteLine($"RandomRead: file/offsets = {refs.Count}"); + + var blobDurations = new List(); + var fileDurations = new List(); + for (var l = 0; l < 10; l++) + { + var subSetRefs = refs.OrderBy(_ => RandomNumberGenerator.GetInt32(100000000)).Take(count).ToList(); + var sw = Stopwatch.StartNew(); + var resources = GetRawResourceFromAdls(subSetRefs, true, parall); + blobDurations.Add(sw.Elapsed.TotalMilliseconds); + Console.WriteLine($"BLOB.RandomRead.{resources.Count}.parall={parall}: total={sw.Elapsed.TotalMilliseconds} msec perLine={sw.Elapsed.TotalMilliseconds / resources.Count} msec"); + subSetRefs = refs.OrderBy(_ => RandomNumberGenerator.GetInt32(100000000)).Take(count).ToList(); + sw = Stopwatch.StartNew(); + resources = GetRawResourceFromAdls(subSetRefs, false, parall); + fileDurations.Add(sw.Elapsed.TotalMilliseconds); + Console.WriteLine($"File.RandomRead.{resources.Count}.parall={parall}: total={sw.Elapsed.TotalMilliseconds} msec perLine={sw.Elapsed.TotalMilliseconds / resources.Count} msec"); + } + + Console.WriteLine($"BLOB.RandomRead.parall={parall}: total={blobDurations.Sum() / 10} msec"); + Console.WriteLine($"File.RandomRead.parall={parall}: total={fileDurations.Sum() / 10} msec"); + } + + public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long TransactionId, int OffsetInFile)> resourceRefs, bool isBlob, int parall) + { + var start = DateTime.UtcNow; + var results = new List(); + if (resourceRefs == null || resourceRefs.Count == 0) + { + return results; + } + + if (isBlob) + { + Parallel.ForEach(resourceRefs, new ParallelOptions { MaxDegreeOfParallelism = parall }, (resourceRef) => + { + var blobName = GetBlobName(resourceRef.TransactionId); + var blobClient = _blobContainer.GetBlobClient(blobName); + using var reader = new StreamReader(blobClient.OpenRead(resourceRef.OffsetInFile)); + var line = reader.ReadLine(); + lock (results) + { + results.Add(line); + } + }); + } + else + { + var resourceRefsByTransaction = resourceRefs.GroupBy(_ => _.TransactionId); + Parallel.ForEach(resourceRefsByTransaction, new ParallelOptions { MaxDegreeOfParallelism = parall }, (group) => + { + var transactionId = group.Key; + var blobName = GetBlobName(transactionId); + var fileClient = _fileSystem.GetFileClient(blobName); + using var stream = fileClient.OpenRead(); //// bufferSize: 1024 * 20); + using var reader = new StreamReader(stream); + foreach (var resourceRef in group.Select(_ => _)) + { + reader.DiscardBufferedData(); + stream.Position = resourceRef.OffsetInFile; + var line = reader.ReadLine(); + lock (results) + { + results.Add(line); + } + } + }); + } + + Source.LogEvent("GetRawResourceFromAdls", "Warn", $"Resources={results.Count}", start); - Export(); + return results; + } + + internal static string GetBlobName(long fileId) + { + return $"hash-{GetPermanentHashCode(fileId)}/transaction-{fileId}.ndjson"; + } + + private static string GetPermanentHashCode(long tr) + { + var hashCode = 0; + foreach (var c in tr.ToString()) // Don't convert to LINQ. This is 10% faster. + { + hashCode = unchecked((hashCode * 251) + c); + } + + return (Math.Abs(hashCode) % 512).ToString().PadLeft(3, '0'); + } + + public static void WriteAndReadAdls(int count, int bufferKB) + { + GetContainer(AdlsUri, AdlsUAMI, "fhir-hs-new-one-file"); + + var fileName = "transaction-353229202.ndjson"; + + var swGlobal = Stopwatch.StartNew(); + + var fileSystem = new DataLakeFileSystemClient(new Uri(AdlsUri), string.IsNullOrEmpty(AdlsUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(AdlsUAMI)); + var fileClient = fileSystem.GetFileClient($"fhir-hs-new-one-file/{fileName}"); + + var offests = new List(); + var offset = 0; + var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); + + var baseLine = string.Concat(Enumerable.Repeat("0123456789", 200)); // 2KB + + using var writeStream = fileClient.OpenWrite(true); + using var writer = new StreamWriter(writeStream); + for (var i = 0; i < count; i++) + { + offests.Add(offset); + var line = $"{offset}\t{baseLine}"; + offset += Encoding.UTF8.GetByteCount(line) + eol; + writer.WriteLine(line); + } + + writer.Flush(); + Console.WriteLine($"ADLS.Write.{count}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); + + swGlobal = Stopwatch.StartNew(); + fileClient = fileSystem.GetFileClient($"testadls/{fileName}"); + using var stream = fileClient.OpenRead(bufferSize: 1024 * bufferKB); + using var reader = new StreamReader(stream); + foreach (var pos in offests) + { + var sw = Stopwatch.StartNew(); + reader.DiscardBufferedData(); + stream.Position = pos; + var line = reader.ReadLine(); + var readOffset = line.Split('\t')[0]; + Console.WriteLine($"ADLS.Read.{count}.buffer={bufferKB}: {sw.Elapsed.TotalMilliseconds} msec (input,read)=({pos},{readOffset})"); } + + Console.WriteLine($"ADLS.Read.{count}.buffer={bufferKB}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); + } + + public static void WriteAndReadBlob(int count, int bufferKB, int parall) + { + var fileName = "test/test/test.txt"; + + var swGlobal = Stopwatch.StartNew(); + + var container = GetContainer(AdlsUri, AdlsUAMI, "testblob"); + + var offests = new List(); + var offset = 0; + var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); + + var baseLine = string.Concat(Enumerable.Repeat("0123456789", 200)); // 2KB + + using var writeStream = container.GetBlockBlobClient(fileName).OpenWrite(true); + using var writer = new StreamWriter(writeStream); + for (var i = 0; i < count; i++) + { + offests.Add(offset); + var line = $"{offset}\t{baseLine}"; + offset += Encoding.UTF8.GetByteCount(line) + eol; + writer.WriteLine(line); + } + + writer.Flush(); + + Console.WriteLine($"BLOB.Write.{count}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); + + swGlobal = Stopwatch.StartNew(); + container = GetContainer(AdlsUri, AdlsUAMI, "testblob"); + var blobClient = container.GetBlobClient(fileName); + Parallel.ForEach(offests, new ParallelOptions { MaxDegreeOfParallelism = parall }, (pos) => + { + var sw = Stopwatch.StartNew(); + using var readStream = blobClient.OpenRead(pos, bufferSize: 1024 * bufferKB); + using var reader = new StreamReader(readStream); + var line = reader.ReadLine(); + var readOffset = line.Split('\t')[0]; + Console.WriteLine($"BLOB.Read.{count}: {sw.Elapsed.TotalMilliseconds} msec (input,read)=({pos},{readOffset})"); + }); + + Console.WriteLine($"BLOB.Read.{count}.buffer={bufferKB}.parall={parall}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); } public static void ExportNoQueue() { var startId = LastUpdatedToResourceSurrogateId(StartDate); var endId = LastUpdatedToResourceSurrogateId(EndDate); - var resourceTypeId = Store.GetResourceTypeId(ResourceType); - var ranges = Store.GetSurrogateIdRanges(resourceTypeId, startId, endId, UnitSize).ToList(); - Console.WriteLine($"ExportNoQueue.{ResourceType}: ranges={ranges.Count}."); - var container = GetContainer(BlobConnectionString, BlobContainerName); + var resourceTypeId = Source.GetResourceTypeId(ResourceType); + var ranges = Source.GetSurrogateIdRanges(resourceTypeId, startId, endId, UnitSize, (int)(2e9 / UnitSize)).ToList(); + Console.WriteLine($"ExportNoSource.{ResourceType}: ranges={ranges.Count}."); + var container = GetContainer(AdlsUri, AdlsUAMI, AdlsContainerName); foreach (var range in ranges) { Export(resourceTypeId, container, range.StartId, range.EndId); @@ -82,14 +307,14 @@ public static void ExportNoQueue() { if (_swReport.Elapsed.TotalSeconds > ReportingPeriodSec) { - Console.WriteLine($"ExportNoQueue.{ResourceType}.threads={Threads}.Writes={WritesEnabled}.Decompress={DecompressEnabled}.Reads={ReadsEnabled}: Resources={_resourcesTotal} secs={(int)_sw.Elapsed.TotalSeconds} speed={(int)(_resourcesTotal / _sw.Elapsed.TotalSeconds)} resources/sec DB={_database.Elapsed.TotalSeconds} sec UnZip={_unzip.Elapsed.TotalSeconds} sec Blob={_blob.Elapsed.TotalSeconds}"); + Console.WriteLine($"ExportNoSource.{ResourceType}.threads={Threads}.Writes={WritesEnabled}.Decompress={DecompressEnabled}.Reads={ReadsEnabled}: Resources={_resourcesTotal} secs={(int)_sw.Elapsed.TotalSeconds} speed={(int)(_resourcesTotal / _sw.Elapsed.TotalSeconds)} resources/sec DB={_database.Elapsed.TotalSeconds} sec UnZip={_unzip.Elapsed.TotalSeconds} sec Blob={_blob.Elapsed.TotalSeconds}"); _swReport.Restart(); } } } } - Console.WriteLine($"ExportNoQueue.{ResourceType}.threads={Threads}: {(stop ? "FAILED" : "completed")} at {DateTime.Now:s}, resources={_resourcesTotal} speed={_resourcesTotal / _sw.Elapsed.TotalSeconds:N0} resources/sec elapsed={_sw.Elapsed.TotalSeconds:N0} sec DB={_database.Elapsed.TotalSeconds} sec UnZip={_unzip.Elapsed.TotalSeconds} sec Blob={_blob.Elapsed.TotalSeconds}"); + Console.WriteLine($"ExportNoSource.{ResourceType}.threads={Threads}: {(stop ? "FAILED" : "completed")} at {DateTime.Now:s}, resources={_resourcesTotal} speed={_resourcesTotal / _sw.Elapsed.TotalSeconds:N0} resources/sec elapsed={_sw.Elapsed.TotalSeconds:N0} sec DB={_database.Elapsed.TotalSeconds} sec UnZip={_unzip.Elapsed.TotalSeconds} sec Blob={_blob.Elapsed.TotalSeconds}"); } public static void Export() @@ -120,15 +345,15 @@ private static void Export(int thread) var version = 0L; var retries = 0; var maxRetries = MaxRetries; - retry: +retry: try { - Store.DequeueJob(out var _, out unitId, out version, out resourceTypeId, out minId, out maxId); + Source.DequeueJob(out var _, out unitId, out version, out resourceTypeId, out minId, out maxId); if (resourceTypeId.HasValue) { - var container = GetContainer(BlobConnectionString, BlobContainerName); + var container = GetContainer(AdlsUri, AdlsUAMI, AdlsContainerName); var resources = Export(resourceTypeId.Value, container, long.Parse(minId), long.Parse(maxId)); - Store.CompleteJob(unitId, false, version, resources); + Source.CompleteJob(unitId, false, version, resources); } if (_swReport.Elapsed.TotalSeconds > ReportingPeriodSec) @@ -146,9 +371,9 @@ private static void Export(int thread) catch (Exception e) { Console.WriteLine($"Export.{ResourceType}.{thread}.{minId}.{maxId}: error={e}"); - Store.SqlRetryService.TryLogEvent($"Export:{ResourceType}.{thread}.{minId}.{maxId}", "Error", e.ToString(), null, CancellationToken.None).Wait(); + Source.LogEvent($"Export", "Error", $"{ResourceType}.{thread}.{minId}.{maxId}: error={e}", DateTime.Now); retries++; - var isRetryable = e.IsRetriable(); + var isRetryable = e.IsRetryable(); if (isRetryable) { maxRetries++; @@ -163,7 +388,7 @@ private static void Export(int thread) stop = true; if (resourceTypeId.HasValue) { - Store.CompleteJob(unitId, true, version); + Source.CompleteJob(unitId, true, version); } throw; @@ -181,7 +406,7 @@ private static int Export(short resourceTypeId, BlobContainerClient container, l } _database.Start(); - var resources = Store.GetDataBytes(resourceTypeId, minId, maxId).ToList(); // ToList will fource reading from SQL even when writes are disabled + var resources = Source.GetDataBytes(resourceTypeId, minId, maxId).ToList(); // ToList will fource reading from SQL even when writes are disabled _database.Stop(); var strings = new List(); @@ -209,9 +434,9 @@ private static int Export(short resourceTypeId, BlobContainerClient container, l return strings.Count; } - private static void WriteBatchOfLines(BlobContainerClient container, IReadOnlyCollection batch, string blobName) + private static void WriteBatchOfLines(BlobContainerClient container, IEnumerable batch, string blobName) { - retry: +retry: try { using var stream = container.GetBlockBlobClient(blobName).OpenWrite(true); @@ -235,31 +460,29 @@ private static void WriteBatchOfLines(BlobContainerClient container, IReadOnlyCo } } - private static BlobContainerClient GetContainer(string connectionString, string containerName) + private static BlobContainerClient GetContainer(string adlsUri, string adlsUAMI, string adlsContainerName) { try { - var blobServiceClient = new BlobServiceClient(connectionString); - var blobContainerClient = blobServiceClient.GetBlobContainerClient(containerName); + if (string.IsNullOrEmpty(adlsUri)) + { + throw new ArgumentNullException(nameof(adlsUri)); + } + + var blobServiceClient = new BlobServiceClient(new Uri(adlsUri), string.IsNullOrEmpty(adlsUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(adlsUAMI)); + var blobContainerClient = blobServiceClient.GetBlobContainerClient(adlsContainerName); if (!blobContainerClient.Exists()) { - lock (_sw) // lock on anything global - { - blobContainerClient = blobServiceClient.GetBlobContainerClient(containerName); - if (!blobContainerClient.Exists()) - { - var container = blobServiceClient.CreateBlobContainer(containerName); - Console.WriteLine($"Created container {container.Value.Name}"); - } - } + var container = blobServiceClient.CreateBlobContainer(adlsContainerName); + Console.WriteLine($"Created container {container.Value.Name}"); } return blobContainerClient; } catch { - Console.WriteLine($"Unable to parse stroage reference or connect to storage account {connectionString}."); + Console.WriteLine($"Unable to parse stroage reference or connect to storage account {adlsUri}."); throw; } } @@ -268,11 +491,12 @@ private static void PopulateJobQueue(string resourceType, int unitSize) { var startId = LastUpdatedToResourceSurrogateId(StartDate); var endId = LastUpdatedToResourceSurrogateId(EndDate); - var resourceTypeId = Store.GetResourceTypeId(resourceType); - var ranges = Store.GetSurrogateIdRanges(resourceTypeId, startId, endId, unitSize); - var strings = ranges.Select(_ => $"{_.UnitId};{resourceTypeId};{_.StartId};{_.EndId};{_.ResourceCount}").ToList(); + var resourceTypeId = Source.GetResourceTypeId(resourceType); + var ranges = Source.GetSurrogateIdRanges(resourceTypeId, startId, endId, unitSize, (int)(2e9 / unitSize)); + + var strings = ranges.Select(_ => $"{0};{resourceTypeId};{_.StartId};{_.EndId};{0}").ToList(); - var queueConn = new SqlConnection(Store.ConnectionString); + var queueConn = new SqlConnection(Source.ConnectionString); queueConn.Open(); using var drop = new SqlCommand("IF object_id('##StoreCopyWorkQueue') IS NOT NULL DROP TABLE ##StoreCopyWorkQueue", queueConn) { CommandTimeout = 60 }; drop.ExecuteNonQuery(); diff --git a/tools/Exporter/Properties/launchSettings.json b/tools/Exporter/Properties/launchSettings.json new file mode 100644 index 0000000000..7fe301173c --- /dev/null +++ b/tools/Exporter/Properties/launchSettings.json @@ -0,0 +1,8 @@ +{ + "profiles": { + "Exporter": { + "commandName": "Project", + "commandLineArgs": "random" + } + } +} \ No newline at end of file diff --git a/tools/Exporter/SqlParamaterStringExtension.cs b/tools/Exporter/SqlParamaterStringExtension.cs index 4db3e241f6..ca78ac5afd 100644 --- a/tools/Exporter/SqlParamaterStringExtension.cs +++ b/tools/Exporter/SqlParamaterStringExtension.cs @@ -5,8 +5,8 @@ using System.Collections.Generic; using System.Data; -using System.Data.SqlClient; -using Microsoft.SqlServer.Server; +using Microsoft.Data.SqlClient; +using Microsoft.Data.SqlClient.Server; namespace Microsoft.Health.Fhir.Store.Export { diff --git a/tools/Exporter/SqlService.cs b/tools/Exporter/SqlService.cs index c829a783fa..b3ec59b86c 100644 --- a/tools/Exporter/SqlService.cs +++ b/tools/Exporter/SqlService.cs @@ -4,9 +4,9 @@ // ------------------------------------------------------------------------------------------------- using System.Collections.Generic; using System.Data; -using System.Data.SqlClient; using System.IO; using System.Threading; +using Microsoft.Data.SqlClient; using Microsoft.Extensions.Logging.Abstractions; using Microsoft.Health.Fhir.Core.Features.Operations; using Microsoft.Health.Fhir.SqlServer.Features.Storage; @@ -35,6 +35,12 @@ public SqlService(string connectionString) public SqlRetryService SqlRetryService => _sqlRetryService; + internal string ShowConnectionString() + { + var builder = new SqlConnectionStringBuilder(_connectionString); + return builder.DataSource + "." + builder.InitialCatalog; + } + internal void DequeueJob(out long groupId, out long jobId, out long version, out short? resourceTypeId, out string minSurIdOrUrl, out string maxSurId) { var jobInfo = _queue.DequeueAsync(_queueType, "A", 600, CancellationToken.None).Result; @@ -62,6 +68,21 @@ internal void CompleteJob(long jobId, bool failed, long version, int? resourceCo _queue.CompleteJobAsync(jobInfo, false, CancellationToken.None).Wait(); } + internal IEnumerable<(long FileId, int OffsetInFile)> GetRefs(short resourceTypeId, long minId, long maxId) + { + using var conn = new SqlConnection(ConnectionString); + conn.Open(); + using var cmd = new SqlCommand("SELECT FileId, OffsetInFile FROM dbo.Resource WHERE IsHistory = 0 AND ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId BETWEEN @StartId AND @EndId", conn) { CommandTimeout = 600 }; + cmd.Parameters.AddWithValue("@ResourceTypeId", resourceTypeId); + cmd.Parameters.AddWithValue("@StartId", minId); + cmd.Parameters.AddWithValue("@EndId", maxId); + using var reader = cmd.ExecuteReader(); + while (reader.Read()) + { + yield return (reader.GetInt64(0), reader.GetInt32(1)); + } + } + internal IEnumerable GetDataBytes(short resourceTypeId, long minId, long maxId) { using var conn = new SqlConnection(ConnectionString); @@ -77,7 +98,7 @@ internal IEnumerable GetDataBytes(short resourceTypeId, long minId, long } } - internal IEnumerable<(int UnitId, long StartId, long EndId, int ResourceCount)> GetSurrogateIdRanges(short resourceTypeId, long startId, long endId, int unitSize) + internal IEnumerable<(int UnitId, long StartId, long EndId, int ResourceCount)> GetSurrogateIdRanges(short resourceTypeId, long startId, long endId, int unitSize, int numberOfRanges) { using var conn = new SqlConnection(ConnectionString); conn.Open(); @@ -85,8 +106,8 @@ internal IEnumerable GetDataBytes(short resourceTypeId, long minId, long cmd.Parameters.AddWithValue("@ResourceTypeId", resourceTypeId); cmd.Parameters.AddWithValue("@StartId", startId); cmd.Parameters.AddWithValue("@EndId", endId); - cmd.Parameters.AddWithValue("@UnitSize", unitSize); - cmd.Parameters.AddWithValue("@NumberOfRanges", (int)(2e9 / unitSize)); + cmd.Parameters.AddWithValue("@RangeSize", unitSize); + cmd.Parameters.AddWithValue("@NumberOfRanges", numberOfRanges); using var reader = cmd.ExecuteReader(); while (reader.Read()) { @@ -118,5 +139,10 @@ internal IEnumerable GetDataStrings(short resourceTypeId, long minId, lo yield return Health.Fhir.Store.Export.CompressedRawResourceConverterCopy.ReadCompressedRawResource(mem); } } + + internal void LogEvent(string process, string status, string text, DateTime start) + { + _sqlRetryService.TryLogEvent(process, status, text, start, CancellationToken.None).Wait(); + } } } From 567b839651758054607698f7c30e3bc772514fe7 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 26 Dec 2024 15:15:32 -0800 Subject: [PATCH 075/111] group read --- .../Features/Storage/SqlStoreClient.cs | 25 +++++++++++++++++++ 1 file changed, 25 insertions(+) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 048f17481d..8b08ed6642 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -94,6 +94,31 @@ public async Task> GetAsync(IReadOnlyList GetRawResourcesFromAdls(IReadOnlyList<(long FileId, int OffsetInFile)> resourceRefs) + { + var start = DateTime.UtcNow; + var resourceRefsByFile = resourceRefs.GroupBy(_ => _.FileId); + var results = new Dictionary<(long FileId, int OffsetInFile), string>(); + if (resourceRefs == null || resourceRefs.Count == 0) + { + return results; + } + + foreach (var file in resourceRefsByFile) + { + var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(file.Key); + var blobClient = SqlAdlsCient.Container.GetBlobClient(blobName); + foreach (var offset in file.Select(_ => _)) + { + using var reader = new StreamReader(blobClient.OpenRead(offset.OffsetInFile)); + var line = reader.ReadLine(); + results.Add((file.Key, offset.OffsetInFile), line); + } + } + + return results; + } + public static Lazy GetRawResourceFromAdls(long fileId, int offsetInFile) { return new Lazy(() => From d8fc0d7db5cc06c642db104062d3bd2dcb594d57 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 11:28:32 -0800 Subject: [PATCH 076/111] Accomodate CurrentResource view --- .../Persistence/SqlServerFhirStorageTestHelper.cs | 5 ++--- 1 file changed, 2 insertions(+), 3 deletions(-) diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs index 11697ffbd0..55b60ffb28 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerFhirStorageTestHelper.cs @@ -322,7 +322,7 @@ async Task IFhirStorageTestHelper.ValidateSnapshotTokenIsCurrent(object snapshot { outerCommand.CommandText = @" SELECT t.name - FROM (SELECT name, object_id FROM sys.objects WHERE name NOT IN ('CurrentResources', 'HistoryResources', 'RawResources') AND type IN ('u','v')) t + FROM (SELECT name, object_id FROM sys.objects WHERE name NOT IN ('CurrentResource', 'CurrentResources', 'HistoryResources', 'RawResources') AND type IN ('u','v')) t JOIN sys.columns c ON c.object_id = t.object_id WHERE c.name = 'ResourceSurrogateId'"; @@ -336,8 +336,7 @@ SELECT t.name } string tableName = reader.GetString(0); - var where = tableName == "Resource" ? "WHERE RawResource <> 0xF" : string.Empty; - sb.AppendLine($"SELECT '{tableName}' as TableName, MAX(ResourceSurrogateId) as MaxResourceSurrogateId FROM dbo.{tableName} {where}"); + sb.AppendLine($"SELECT '{tableName}', max(ResourceSurrogateId) FROM dbo.{tableName} {(tableName == "Resource" ? "WHERE RawResource <> 0xF" : string.Empty)}"); } } } From 0f0091545c5369107953872bfefab769a21b42ca Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 11:33:10 -0800 Subject: [PATCH 077/111] Switched search to set file reads --- .../Features/Search/SqlServerSearchService.cs | 84 ++++++++++------- .../Features/Storage/SqlStoreClient.cs | 32 +++---- tools/Exporter/Program.cs | 94 +++++++++++++++++-- 3 files changed, 148 insertions(+), 62 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 7c9a45e4d7..56297234a6 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -409,7 +409,7 @@ await _sqlRetryService.ExecuteSql( return; } - var resources = new List(sqlSearchOptions.MaxItemCount); + var tmpResources = new List<(SearchResultEntry Entry, bool IsMetaSet, SqlBytes SqlBytes, long? FileId, int? OffsetInFile)>(sqlSearchOptions.MaxItemCount); short? newContinuationType = null; long? newContinuationId = null; bool moreResults = false; @@ -451,26 +451,6 @@ await _sqlRetryService.ExecuteSql( continue; } - Lazy rawResource = new Lazy(() => string.Empty); - - if (!clonedSearchOptions.OnlyIds) - { - rawResource = new Lazy(() => - { - var decompressedResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, fileId, offsetInFile); - - _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(resourceSurrogateId), resourceSurrogateId, nameof(resourceTypeId), resourceTypeId, decompressedResource.Length); - - if (string.IsNullOrEmpty(decompressedResource)) - { - decompressedResource = MissingResourceFactory.CreateJson(resourceId, _model.GetResourceTypeName(resourceTypeId), "warning", "incomplete"); - _requestContextAccessor.SetMissingResourceCode(System.Net.HttpStatusCode.PartialContent); - } - - return decompressedResource; - }); - } - // See if this resource is a continuation token candidate and increase the count if (isMatch) { @@ -499,26 +479,58 @@ await _sqlRetryService.ExecuteSql( // should be marked as partial isResultPartial = isResultPartial || isPartialEntry; - resources.Add(new SearchResultEntry( - new ResourceWrapper( - resourceId, - version.ToString(CultureInfo.InvariantCulture), - _model.GetResourceTypeName(resourceTypeId), - clonedSearchOptions.OnlyIds ? null : new RawResource(rawResource, FhirResourceFormat.Json, isMetaSet: isRawResourceMetaSet), - new ResourceRequest(requestMethod), - resourceSurrogateId.ToLastUpdated(), - isDeleted, - null, - null, - null, - searchParameterHash, - resourceSurrogateId), - isMatch ? SearchEntryMode.Match : SearchEntryMode.Include)); + tmpResources.Add((new SearchResultEntry( + new ResourceWrapper( + resourceId, + version.ToString(CultureInfo.InvariantCulture), + _model.GetResourceTypeName(resourceTypeId), + null, + new ResourceRequest(requestMethod), + resourceSurrogateId.ToLastUpdated(), + isDeleted, + null, + null, + null, + searchParameterHash, + resourceSurrogateId), + isMatch ? SearchEntryMode.Match : SearchEntryMode.Include), + isRawResourceMetaSet, + rawResourceSqlBytes, + fileId, + offsetInFile)); } // call NextResultAsync to get the info messages await reader.NextResultAsync(cancellationToken); + // add raw resource to search entry + var resources = new List(sqlSearchOptions.MaxItemCount); + var rawReaources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes == null).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); + foreach (var tmpResource in tmpResources) + { + if (!clonedSearchOptions.OnlyIds) + { + var rawResource = new Lazy(() => + { + var decompressed = tmpResource.SqlBytes.IsNull + ? rawReaources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] + : SqlStoreClient.ReadRawResource(tmpResource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, tmpResource.FileId, tmpResource.OffsetInFile); + _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(tmpResource.Entry.Resource.ResourceSurrogateId), tmpResource.Entry.Resource.ResourceSurrogateId, nameof(tmpResource.Entry.Resource.ResourceTypeName), tmpResource.Entry.Resource.ResourceTypeName, decompressed.Length); + if (string.IsNullOrEmpty(decompressed)) + { + decompressed = MissingResourceFactory.CreateJson(tmpResource.Entry.Resource.ResourceId, tmpResource.Entry.Resource.ResourceTypeName, "warning", "incomplete"); + _requestContextAccessor.SetMissingResourceCode(System.Net.HttpStatusCode.PartialContent); + } + + return decompressed; + }); + + tmpResource.Entry.Resource.RawResource = new RawResource(rawResource, FhirResourceFormat.Json, isMetaSet: tmpResource.IsMetaSet); + } + + resources.Add(tmpResource.Entry); + } + ContinuationToken continuationToken = moreResults ? new ContinuationToken( clonedSearchOptions.Sort.Select(s => diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 8b08ed6642..6e6403201f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -96,7 +96,11 @@ public async Task> GetAsync(IReadOnlyList GetRawResourcesFromAdls(IReadOnlyList<(long FileId, int OffsetInFile)> resourceRefs) { - var start = DateTime.UtcNow; + if (SqlAdlsCient.Container == null) + { + throw new InvalidOperationException("ADLS container is null."); + } + var resourceRefsByFile = resourceRefs.GroupBy(_ => _.FileId); var results = new Dictionary<(long FileId, int OffsetInFile), string>(); if (resourceRefs == null || resourceRefs.Count == 0) @@ -108,9 +112,12 @@ public async Task> GetAsync(IReadOnlyList _)) { - using var reader = new StreamReader(blobClient.OpenRead(offset.OffsetInFile)); + reader.DiscardBufferedData(); + stream.Position = offset.OffsetInFile; var line = reader.ReadLine(); results.Add((file.Key, offset.OffsetInFile), line); } @@ -119,20 +126,12 @@ public async Task> GetAsync(IReadOnlyList GetRawResourceFromAdls(long fileId, int offsetInFile) + // TODO: Remove after changing get async code + public static string GetRawResourceFromAdls(long fileId, int offsetInFile) { - return new Lazy(() => - { - var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(fileId); - if (SqlAdlsCient.Container == null) - { - throw new InvalidOperationException("ADLS container is null."); - } - - using var reader = new StreamReader(SqlAdlsCient.Container.GetBlobClient(blobName).OpenRead(offsetInFile)); - var line = reader.ReadLine(); - return line; - }); + var refs = new List<(long FileId, int OffsetInFile)> { (fileId, offsetInFile) }; + var result = GetRawResourcesFromAdls(refs); + return result[(fileId, offsetInFile)]; } public async Task> GetResourceVersionsAsync(IReadOnlyList keys, Func decompress, CancellationToken cancellationToken) @@ -172,13 +171,14 @@ public static Lazy GetRawResourceFromAdls(long fileId, int offsetInFile) return resources; } + // TODO: Remove file id and offset internal static string ReadRawResource(SqlBytes bytes, Func decompress, long? fileId, int? offsetInFile) { var rawResourceBytes = bytes.IsNull ? null : bytes.Value; string rawResource; if (rawResourceBytes == null && offsetInFile.HasValue) // raw in adls { - rawResource = GetRawResourceFromAdls(fileId.Value, offsetInFile.Value).Value; + rawResource = GetRawResourceFromAdls(fileId.Value, offsetInFile.Value); } else if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) // invisible resource { diff --git a/tools/Exporter/Program.cs b/tools/Exporter/Program.cs index 4193da3dcc..3bc08513d5 100644 --- a/tools/Exporter/Program.cs +++ b/tools/Exporter/Program.cs @@ -56,7 +56,7 @@ public static class Program public static void Main(string[] args) { - if (args.Length > 0 && args[0] == "random") + if (args.Length > 0 && (args[0] == "random" || args[0] == "sorted")) { var count = args.Length > 1 ? int.Parse(args[1]) : 100; _blobContainer = GetContainer(AdlsUri, AdlsUAMI, AdlsContainerName); @@ -71,7 +71,14 @@ public static void Main(string[] args) var parall = args.Length > 2 ? int.Parse(args[2]) : 8; - RandomReads(count, parall); + if (args[0] == "random") + { + RandomReads(count, parall); + } + else + { + SortedReads(count, parall); + } } else if (args.Length == 0 || args[0] == "storage") { @@ -132,7 +139,55 @@ public static void RandomReads(int count, int parall) Console.WriteLine($"File.RandomRead.parall={parall}: total={fileDurations.Sum() / 10} msec"); } - public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long TransactionId, int OffsetInFile)> resourceRefs, bool isBlob, int parall) + public static void SortedReads(int count, int parall) + { + var maxId = LastUpdatedToResourceSurrogateId(DateTime.UtcNow); + var ranges = Source.GetSurrogateIdRanges(96, 0, maxId, 10000, 10000); + var refs = new List<(long FileId, int OffsetInFile)>(); + foreach (var range in ranges) + { + refs.AddRange(Source.GetRefs(96, range.StartId, range.EndId)); + } + + Console.WriteLine($"SortedRead: file/offsets = {refs.Count}"); + + var blobDurations = new List(); + var fileDurations = new List(); + var blobResources = 0L; + var fileResources = 0L; + var loop = 0; + foreach (var r in refs.GroupBy(_ => _.FileId)) + { + var subSetRefs = r.Select(_ => _).ToList(); + + var sw = Stopwatch.StartNew(); + var resources = GetRawResourceFromAdls(subSetRefs, true, parall); + Console.WriteLine($"Ignore BLOB.SortedRead.{resources.Count}.parall={parall}: total={sw.Elapsed.TotalMilliseconds} msec perLine={sw.Elapsed.TotalMilliseconds / resources.Count} msec"); + + sw = Stopwatch.StartNew(); + resources = GetRawResourceFromAdls(subSetRefs, false, parall); + fileDurations.Add(sw.Elapsed.TotalMilliseconds); + fileResources += resources.Sum(_ => _.Length); + Console.WriteLine($"File.SortedRead.{resources.Count}.parall={parall}: total={sw.Elapsed.TotalMilliseconds} msec perLine={sw.Elapsed.TotalMilliseconds / resources.Count} msec"); + + sw = Stopwatch.StartNew(); + resources = GetRawResourceFromAdls(subSetRefs, true, parall); + blobDurations.Add(sw.Elapsed.TotalMilliseconds); + blobResources += resources.Sum(_ => _.Length); + Console.WriteLine($"BLOB.SortedRead.{resources.Count}.parall={parall}: total={sw.Elapsed.TotalMilliseconds} msec perLine={sw.Elapsed.TotalMilliseconds / resources.Count} msec"); + + loop++; + if (loop >= 10) + { + break; + } + } + + Console.WriteLine($"BLOB.SortedRead.parall={parall}: resources={blobResources} total={blobDurations.Sum()} msec"); + Console.WriteLine($"File.SortedRead.parall={parall}: resources={fileResources} total={fileDurations.Sum()} msec"); + } + + public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long FileId, int OffsetInFile)> resourceRefs, bool isBlob, int parall) { var start = DateTime.UtcNow; var results = new List(); @@ -143,21 +198,40 @@ public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long T if (isBlob) { - Parallel.ForEach(resourceRefs, new ParallelOptions { MaxDegreeOfParallelism = parall }, (resourceRef) => + var resourceRefsByTransaction = resourceRefs.GroupBy(_ => _.FileId); + Parallel.ForEach(resourceRefsByTransaction, new ParallelOptions { MaxDegreeOfParallelism = parall }, (group) => { - var blobName = GetBlobName(resourceRef.TransactionId); + var transactionId = group.Key; + var blobName = GetBlobName(transactionId); var blobClient = _blobContainer.GetBlobClient(blobName); - using var reader = new StreamReader(blobClient.OpenRead(resourceRef.OffsetInFile)); - var line = reader.ReadLine(); - lock (results) + using var stream = blobClient.OpenRead(); + using var reader = new StreamReader(stream); + foreach (var resourceRef in group.Select(_ => _)) { - results.Add(line); + reader.DiscardBufferedData(); + stream.Position = resourceRef.OffsetInFile; + var line = reader.ReadLine(); + lock (results) + { + results.Add(line); + } } }); + ////Parallel.ForEach(resourceRefs, new ParallelOptions { MaxDegreeOfParallelism = parall }, (resourceRef) => + ////{ + //// var blobName = GetBlobName(resourceRef.FileId); + //// var blobClient = _blobContainer.GetBlobClient(blobName); + //// using var reader = new StreamReader(blobClient.OpenRead(resourceRef.OffsetInFile)); + //// var line = reader.ReadLine(); + //// lock (results) + //// { + //// results.Add(line); + //// } + ////}); } else { - var resourceRefsByTransaction = resourceRefs.GroupBy(_ => _.TransactionId); + var resourceRefsByTransaction = resourceRefs.GroupBy(_ => _.FileId); Parallel.ForEach(resourceRefsByTransaction, new ParallelOptions { MaxDegreeOfParallelism = parall }, (group) => { var transactionId = group.Key; From 1a8d6d4ef9555e77531139404b7de531069743a2 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 11:46:14 -0800 Subject: [PATCH 078/111] moved large logic outside of reader --- .../Features/Search/SqlServerSearchService.cs | 65 ++++++++++--------- 1 file changed, 34 insertions(+), 31 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 56297234a6..b15347cc4a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -4,6 +4,7 @@ // ------------------------------------------------------------------------------------------------- using System; +using System.ClientModel; using System.Collections; using System.Collections.Concurrent; using System.Collections.Generic; @@ -383,6 +384,9 @@ await _sqlRetryService.ExecuteSql( LogSqlCommand(sqlCommand); + ContinuationToken continuationToken = null; + var tmpResources = new List<(SearchResultEntry Entry, bool IsMetaSet, SqlBytes SqlBytes, long? FileId, int? OffsetInFile)>(sqlSearchOptions.MaxItemCount); + //// logic inside sql reader should be as short as possible using (var reader = await sqlCommand.ExecuteReaderAsync(CommandBehavior.SequentialAccess, cancellationToken)) { if (clonedSearchOptions.CountOnly) @@ -409,7 +413,6 @@ await _sqlRetryService.ExecuteSql( return; } - var tmpResources = new List<(SearchResultEntry Entry, bool IsMetaSet, SqlBytes SqlBytes, long? FileId, int? OffsetInFile)>(sqlSearchOptions.MaxItemCount); short? newContinuationType = null; long? newContinuationId = null; bool moreResults = false; @@ -503,35 +506,7 @@ await _sqlRetryService.ExecuteSql( // call NextResultAsync to get the info messages await reader.NextResultAsync(cancellationToken); - // add raw resource to search entry - var resources = new List(sqlSearchOptions.MaxItemCount); - var rawReaources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes == null).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); - foreach (var tmpResource in tmpResources) - { - if (!clonedSearchOptions.OnlyIds) - { - var rawResource = new Lazy(() => - { - var decompressed = tmpResource.SqlBytes.IsNull - ? rawReaources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] - : SqlStoreClient.ReadRawResource(tmpResource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, tmpResource.FileId, tmpResource.OffsetInFile); - _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(tmpResource.Entry.Resource.ResourceSurrogateId), tmpResource.Entry.Resource.ResourceSurrogateId, nameof(tmpResource.Entry.Resource.ResourceTypeName), tmpResource.Entry.Resource.ResourceTypeName, decompressed.Length); - if (string.IsNullOrEmpty(decompressed)) - { - decompressed = MissingResourceFactory.CreateJson(tmpResource.Entry.Resource.ResourceId, tmpResource.Entry.Resource.ResourceTypeName, "warning", "incomplete"); - _requestContextAccessor.SetMissingResourceCode(System.Net.HttpStatusCode.PartialContent); - } - - return decompressed; - }); - - tmpResource.Entry.Resource.RawResource = new RawResource(rawResource, FhirResourceFormat.Json, isMetaSet: tmpResource.IsMetaSet); - } - - resources.Add(tmpResource.Entry); - } - - ContinuationToken continuationToken = moreResults + continuationToken = moreResults ? new ContinuationToken( clonedSearchOptions.Sort.Select(s => s.searchParameterInfo.Name switch @@ -572,9 +547,37 @@ await _sqlRetryService.ExecuteSql( { sqlSearchOptions.SortHasMissingModifier = true; } + } - searchResult = new SearchResult(resources, continuationToken?.ToJson(), originalSort, clonedSearchOptions.UnsupportedSearchParams); + // add raw resource to search entry + var resources = new List(sqlSearchOptions.MaxItemCount); + var rawReaources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes == null).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); + foreach (var tmpResource in tmpResources) + { + if (!clonedSearchOptions.OnlyIds) + { + var rawResource = new Lazy(() => + { + var decompressed = tmpResource.SqlBytes.IsNull + ? rawReaources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] + : SqlStoreClient.ReadRawResource(tmpResource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, tmpResource.FileId, tmpResource.OffsetInFile); + _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(tmpResource.Entry.Resource.ResourceSurrogateId), tmpResource.Entry.Resource.ResourceSurrogateId, nameof(tmpResource.Entry.Resource.ResourceTypeName), tmpResource.Entry.Resource.ResourceTypeName, decompressed.Length); + if (string.IsNullOrEmpty(decompressed)) + { + decompressed = MissingResourceFactory.CreateJson(tmpResource.Entry.Resource.ResourceId, tmpResource.Entry.Resource.ResourceTypeName, "warning", "incomplete"); + _requestContextAccessor.SetMissingResourceCode(System.Net.HttpStatusCode.PartialContent); + } + + return decompressed; + }); + + tmpResource.Entry.Resource.RawResource = new RawResource(rawResource, FhirResourceFormat.Json, isMetaSet: tmpResource.IsMetaSet); + } + + resources.Add(tmpResource.Entry); } + + searchResult = new SearchResult(resources, continuationToken?.ToJson(), originalSort, clonedSearchOptions.UnsupportedSearchParams); } }, _logger, From ba9bfc0737b40ab378dacaf6e94a7c517a4861db Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 15:16:59 -0800 Subject: [PATCH 079/111] refactored to use set reads --- .../Features/Search/SqlServerSearchService.cs | 72 ++++++++------ .../Features/Storage/SqlStoreClient.cs | 96 +++++++++++-------- 2 files changed, 99 insertions(+), 69 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index b15347cc4a..929374795c 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -45,6 +45,7 @@ using Microsoft.Health.SqlServer.Features.Schema; using Microsoft.Health.SqlServer.Features.Schema.Model; using Microsoft.Health.SqlServer.Features.Storage; +using static System.Net.WebRequestMethods; using SortOrder = Microsoft.Health.Fhir.Core.Features.Search.SortOrder; namespace Microsoft.Health.Fhir.SqlServer.Features.Search @@ -559,8 +560,8 @@ await _sqlRetryService.ExecuteSql( var rawResource = new Lazy(() => { var decompressed = tmpResource.SqlBytes.IsNull - ? rawReaources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] - : SqlStoreClient.ReadRawResource(tmpResource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, tmpResource.FileId, tmpResource.OffsetInFile); + ? rawReaources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] + : SqlStoreClient.ReadCompressedRawResource(tmpResource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource); _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(tmpResource.Entry.Resource.ResourceSurrogateId), tmpResource.Entry.Resource.ResourceSurrogateId, nameof(tmpResource.Entry.Resource.ResourceTypeName), tmpResource.Entry.Resource.ResourceTypeName, decompressed.Length); if (string.IsNullOrEmpty(decompressed)) { @@ -638,13 +639,13 @@ public async Task SearchBySurrogateIdRange(string resourceType, lo sqlCommand.CommandTimeout = GetReindexCommandTimeout(); PopulateSqlCommandFromQueryHints(sqlCommand, resourceTypeId, startId, endId, windowEndId, includeHistory, includeDeleted); LogSqlCommand(sqlCommand); - List resources = null; + List<(SearchResultEntry Entry, SqlBytes SqlBytes, long? FileId, int? OffsetInFile, bool IsMetaSet, string ResourceId)> resources = null; await _sqlRetryService.ExecuteSql( sqlCommand, async (cmd, cancel) => { using SqlDataReader reader = await cmd.ExecuteReaderAsync(CommandBehavior.SequentialAccess, cancel); - resources = new List(); + resources = new List<(SearchResultEntry Entry, SqlBytes SqlBytes, long? FileId, int? OffsetInFile, bool IsMetaSet, string ResourceId)>(); while (await reader.ReadAsync(cancel)) { ReadWrapper( @@ -675,29 +676,27 @@ await _sqlRetryService.ExecuteSql( continue; } - var rawResource = SqlStoreClient.ReadRawResource(rawResourceSqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource, fileId, offsetInFile); - - if (string.IsNullOrEmpty(rawResource)) - { - rawResource = MissingResourceFactory.CreateJson(resourceId, _model.GetResourceTypeName(resourceTypeId), "warning", "incomplete"); - _requestContextAccessor.SetMissingResourceCode(System.Net.HttpStatusCode.PartialContent); - } - - resources.Add(new SearchResultEntry( - new ResourceWrapper( - resourceId, - version.ToString(CultureInfo.InvariantCulture), - resourceType, - new RawResource(rawResource, FhirResourceFormat.Json, isMetaSet: isRawResourceMetaSet), - new ResourceRequest(requestMethod), - resourceSurrogateId.ToLastUpdated(), - isDeleted, - null, - null, - null, - searchParameterHash, - resourceSurrogateId), - isMatch ? SearchEntryMode.Match : SearchEntryMode.Include)); + resources.Add( + (new SearchResultEntry( + new ResourceWrapper( + resourceId, + version.ToString(CultureInfo.InvariantCulture), + resourceType, + null, + new ResourceRequest(requestMethod), + resourceSurrogateId.ToLastUpdated(), + isDeleted, + null, + null, + null, + searchParameterHash, + resourceSurrogateId), + isMatch ? SearchEntryMode.Match : SearchEntryMode.Include), + rawResourceSqlBytes, + fileId, + offsetInFile, + isRawResourceMetaSet, + resourceId)); } return; @@ -705,7 +704,24 @@ await _sqlRetryService.ExecuteSql( _logger, null, cancellationToken); - return new SearchResult(resources, null, null, new List>()) { TotalCount = resources.Count }; + var refs = resources.Where(_ => _.SqlBytes == null).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList(); + var rawResources = SqlStoreClient.GetRawResourcesFromAdls(refs); + foreach (var resource in resources) + { + var rawResource = resource.SqlBytes.IsNull + ? rawResources[(resource.FileId.Value, resource.OffsetInFile.Value)] + : SqlStoreClient.ReadCompressedRawResource(resource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource); + + if (string.IsNullOrEmpty(rawResource)) + { + rawResource = MissingResourceFactory.CreateJson(resource.ResourceId, _model.GetResourceTypeName(resourceTypeId), "warning", "incomplete"); + _requestContextAccessor.SetMissingResourceCode(System.Net.HttpStatusCode.PartialContent); + } + + resource.Entry.Resource.RawResource = new RawResource(rawResource, FhirResourceFormat.Json, resource.IsMetaSet); + } + + return new SearchResult(resources.Select(_ => _.Entry), null, null, new List>()) { TotalCount = resources.Count }; } private static (long StartId, long EndId) ReaderToSurrogateIdRange(SqlDataReader sqlDataReader) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 6e6403201f..db2d9cd95f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -77,7 +77,7 @@ public async Task> GetAsync(IReadOnlyList { return ReadResourceWrapper(reader, false, decompress, SqlAdlsCient.Container, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).Where(_ => includeInvisible || _.RawResource.Data != InvisibleResource).ToList(); + return await ReadResourceWrappers(cmd, decompress, getResourceTypeName, isReadOnly, false, cancellationToken, includeInvisible); } catch (Exception e) { @@ -94,7 +94,20 @@ public async Task> GetAsync(IReadOnlyList GetRawResourcesFromAdls(IReadOnlyList<(long FileId, int OffsetInFile)> resourceRefs) + private async Task> ReadResourceWrappers(SqlCommand cmd, Func decompress, Func getResourceTypeName, bool isReadOnly, bool readRequestMethod, CancellationToken cancellationToken, bool includeInvisible = false) + { + var wrappers = (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadTemporaryResourceWrapper(reader, readRequestMethod, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).ToList(); + var refs = wrappers.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList(); + var rawResources = GetRawResourcesFromAdls(refs); + foreach (var wrapper in wrappers) + { + wrapper.Wrapper.RawResource = new RawResource(wrapper.SqlBytes.IsNull ? rawResources[(wrapper.FileId.Value, wrapper.OffsetInFile.Value)] : ReadCompressedRawResource(wrapper.SqlBytes, decompress), FhirResourceFormat.Json, wrapper.IsMetaSet); + } + + return wrappers.Where(_ => includeInvisible || _.Wrapper.RawResource.Data != InvisibleResource).Select(_ => _.Wrapper).ToList(); + } + + internal static IDictionary<(long FileId, int OffsetInFile), string> GetRawResourcesFromAdls(IReadOnlyList<(long FileId, int OffsetInFile)> resourceRefs) { if (SqlAdlsCient.Container == null) { @@ -126,12 +139,21 @@ public async Task> GetAsync(IReadOnlyList decompress) { - var refs = new List<(long FileId, int OffsetInFile)> { (fileId, offsetInFile) }; - var result = GetRawResourcesFromAdls(refs); - return result[(fileId, offsetInFile)]; + var rawResourceBytes = bytes.Value; + string rawResource; + if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) // invisible resource + { + rawResource = InvisibleResource; + } + else + { + using var rawResourceStream = new MemoryStream(rawResourceBytes); + rawResource = decompress(rawResourceStream); + } + + return rawResource; } public async Task> GetResourceVersionsAsync(IReadOnlyList keys, Func decompress, CancellationToken cancellationToken) @@ -145,7 +167,7 @@ public static string GetRawResourceFromAdls(long fileId, int offsetInFile) var tvpRows = keys.Select(_ => new ResourceDateKeyListRow(_.ResourceTypeId, _.Id, _.ResourceSurrogateId)); new ResourceDateKeyListTableValuedParameterDefinition("@ResourceDateKeys").AddParameter(cmd.Parameters, tvpRows); var table = VLatest.Resource; - var resources = await cmd.ExecuteReaderAsync( + var tmpResources = await cmd.ExecuteReaderAsync( _sqlRetryService, (reader) => { @@ -154,54 +176,45 @@ public static string GetRawResourceFromAdls(long fileId, int offsetInFile) var resourceSurrogateId = reader.Read(table.ResourceSurrogateId, 2); var version = reader.Read(table.Version, 3); string matchedVersion = null; - RawResource matchedRawResource = null; + SqlBytes matchedBytes = null; + long? matchedFileId = null; + int? matchedOffsetInFile = null; if (version == 0) // there is a match { matchedVersion = reader.Read(table.Version, 4).ToString(); - var bytes = reader.GetSqlBytes(5); - var matchedFileId = reader.FieldCount > 6 ? reader.Read(table.FileId, 6) : null; // TODO: Remove field count check after deployment - var matchedOffsetInFile = reader.FieldCount > 6 ? reader.Read(table.OffsetInFile, 7) : null; - matchedRawResource = new RawResource(ReadRawResource(bytes, decompress, matchedFileId, matchedOffsetInFile), FhirResourceFormat.Json, true); + matchedBytes = reader.GetSqlBytes(5); + matchedFileId = reader.FieldCount > 6 ? reader.Read(table.FileId, 6) : null; // TODO: Remove field count check after deployment + matchedOffsetInFile = reader.FieldCount > 6 ? reader.Read(table.OffsetInFile, 7) : null; } - return (new ResourceDateKey(resourceTypeId, resourceId, resourceSurrogateId, version.ToString(CultureInfo.InvariantCulture)), (matchedVersion, matchedRawResource)); + return (new ResourceDateKey(resourceTypeId, resourceId, resourceSurrogateId, version.ToString(CultureInfo.InvariantCulture)), (matchedVersion, matchedBytes, matchedFileId, matchedOffsetInFile)); }, _logger, cancellationToken); - return resources; - } - - // TODO: Remove file id and offset - internal static string ReadRawResource(SqlBytes bytes, Func decompress, long? fileId, int? offsetInFile) - { - var rawResourceBytes = bytes.IsNull ? null : bytes.Value; - string rawResource; - if (rawResourceBytes == null && offsetInFile.HasValue) // raw in adls - { - rawResource = GetRawResourceFromAdls(fileId.Value, offsetInFile.Value); - } - else if (rawResourceBytes.Length == 1 && rawResourceBytes[0] == 0xF) // invisible resource - { - rawResource = InvisibleResource; - } - else + var refs = tmpResources.Where(_ => _.Item2.matchedVersion != null && _.Item2.matchedBytes.IsNull).Select(_ => (_.Item2.matchedFileId.Value, _.Item2.matchedOffsetInFile.Value)).ToList(); + var rawResources = GetRawResourcesFromAdls(refs); + var resources = tmpResources.Select(_ => { - using var rawResourceStream = new MemoryStream(rawResourceBytes); - rawResource = decompress(rawResourceStream); - } + var (key, (version, bytes, fileId, offsetInFile)) = _; + RawResource rawResource = null; + if (_.Item2.matchedVersion != null) + { + rawResource = new RawResource(bytes.IsNull ? rawResources[(fileId.Value, offsetInFile.Value)] : ReadCompressedRawResource(bytes, decompress), FhirResourceFormat.Json, false); + } - return rawResource; + return (key, (version, rawResource)); + }).ToList(); + return resources; } internal async Task> GetResourcesByTransactionIdAsync(long transactionId, Func decompress, Func getResourceTypeName, CancellationToken cancellationToken) { await using var cmd = new SqlCommand() { CommandText = "dbo.GetResourcesByTransactionId", CommandType = CommandType.StoredProcedure, CommandTimeout = 600 }; cmd.Parameters.AddWithValue("@TransactionId", transactionId); - //// ignore invisible resources - return (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadResourceWrapper(reader, true, decompress, SqlAdlsCient.Container, getResourceTypeName); }, _logger, cancellationToken)).Where(_ => _.RawResource.Data != InvisibleResource).ToList(); + return await ReadResourceWrappers(cmd, decompress, getResourceTypeName, false, true, cancellationToken, false); } - private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func decompress, BlobContainerClient adlsClient, Func getResourceTypeName) + private static (ResourceWrapper Wrapper, bool IsMetaSet, SqlBytes SqlBytes, long? FileId, int? OffsetInFile) ReadTemporaryResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func getResourceTypeName) { var resourceTypeId = reader.Read(VLatest.Resource.ResourceTypeId, 0); var resourceId = reader.Read(VLatest.Resource.ResourceId, 1); @@ -212,15 +225,14 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re var bytes = reader.GetSqlBytes(6); var fileId = reader.FieldCount > 10 ? reader.Read(VLatest.Resource.FileId, readRequestMethod ? 10 : 9) : null; // TODO: Remove field count check after Lake schema deployment var offsetInFile = reader.FieldCount > 10 ? reader.Read(VLatest.Resource.OffsetInFile, readRequestMethod ? 11 : 10) : null; - var rawResource = ReadRawResource(bytes, decompress, fileId, offsetInFile); var isRawResourceMetaSet = reader.Read(VLatest.Resource.IsRawResourceMetaSet, 7); var searchParamHash = reader.Read(VLatest.Resource.SearchParamHash, 8); var requestMethod = readRequestMethod ? reader.Read(VLatest.Resource.RequestMethod, 9) : null; - return new ResourceWrapper( + var wrapper = new ResourceWrapper( resourceId, version.ToString(CultureInfo.InvariantCulture), getResourceTypeName(resourceTypeId), - new RawResource(rawResource, FhirResourceFormat.Json, isMetaSet: isRawResourceMetaSet), + null, readRequestMethod ? new ResourceRequest(requestMethod) : null, resourceSurrogateId.ToLastUpdated(), isDeleted, @@ -232,6 +244,8 @@ private static ResourceWrapper ReadResourceWrapper(SqlDataReader reader, bool re { IsHistory = isHistory, }; + + return (wrapper, isRawResourceMetaSet, bytes, fileId, offsetInFile); } internal async Task MergeResourcesPutTransactionHeartbeatAsync(long transactionId, TimeSpan heartbeatPeriod, CancellationToken cancellationToken) From 0b633b3825086658673f81e06e623c4ae8ba700d Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 15:24:20 -0800 Subject: [PATCH 080/111] alarms --- tools/Exporter/Program.cs | 17 +++-------------- 1 file changed, 3 insertions(+), 14 deletions(-) diff --git a/tools/Exporter/Program.cs b/tools/Exporter/Program.cs index 3bc08513d5..6b261c8762 100644 --- a/tools/Exporter/Program.cs +++ b/tools/Exporter/Program.cs @@ -206,7 +206,7 @@ public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long F var blobClient = _blobContainer.GetBlobClient(blobName); using var stream = blobClient.OpenRead(); using var reader = new StreamReader(stream); - foreach (var resourceRef in group.Select(_ => _)) + foreach (var resourceRef in group) { reader.DiscardBufferedData(); stream.Position = resourceRef.OffsetInFile; @@ -217,17 +217,6 @@ public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long F } } }); - ////Parallel.ForEach(resourceRefs, new ParallelOptions { MaxDegreeOfParallelism = parall }, (resourceRef) => - ////{ - //// var blobName = GetBlobName(resourceRef.FileId); - //// var blobClient = _blobContainer.GetBlobClient(blobName); - //// using var reader = new StreamReader(blobClient.OpenRead(resourceRef.OffsetInFile)); - //// var line = reader.ReadLine(); - //// lock (results) - //// { - //// results.Add(line); - //// } - ////}); } else { @@ -237,9 +226,9 @@ public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long F var transactionId = group.Key; var blobName = GetBlobName(transactionId); var fileClient = _fileSystem.GetFileClient(blobName); - using var stream = fileClient.OpenRead(); //// bufferSize: 1024 * 20); + using var stream = fileClient.OpenRead(); using var reader = new StreamReader(stream); - foreach (var resourceRef in group.Select(_ => _)) + foreach (var resourceRef in group) { reader.DiscardBufferedData(); stream.Position = resourceRef.OffsetInFile; From b751b14d638ab88f86b99ec6cad6642efb62dfe2 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 15:47:04 -0800 Subject: [PATCH 081/111] Corrected != null on SqlBytes --- .../Features/Search/SqlServerSearchService.cs | 5 ++--- .../Features/Storage/SqlStoreClient.cs | 5 ++--- 2 files changed, 4 insertions(+), 6 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 929374795c..3f25b572f7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -552,7 +552,7 @@ await _sqlRetryService.ExecuteSql( // add raw resource to search entry var resources = new List(sqlSearchOptions.MaxItemCount); - var rawReaources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes == null).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); + var rawReaources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); foreach (var tmpResource in tmpResources) { if (!clonedSearchOptions.OnlyIds) @@ -704,8 +704,7 @@ await _sqlRetryService.ExecuteSql( _logger, null, cancellationToken); - var refs = resources.Where(_ => _.SqlBytes == null).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList(); - var rawResources = SqlStoreClient.GetRawResourcesFromAdls(refs); + var rawResources = SqlStoreClient.GetRawResourcesFromAdls(resources.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); foreach (var resource in resources) { var rawResource = resource.SqlBytes.IsNull diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index db2d9cd95f..dcffd47253 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -97,8 +97,7 @@ public async Task> GetAsync(IReadOnlyList> ReadResourceWrappers(SqlCommand cmd, Func decompress, Func getResourceTypeName, bool isReadOnly, bool readRequestMethod, CancellationToken cancellationToken, bool includeInvisible = false) { var wrappers = (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadTemporaryResourceWrapper(reader, readRequestMethod, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).ToList(); - var refs = wrappers.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList(); - var rawResources = GetRawResourcesFromAdls(refs); + var rawResources = GetRawResourcesFromAdls(wrappers.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); foreach (var wrapper in wrappers) { wrapper.Wrapper.RawResource = new RawResource(wrapper.SqlBytes.IsNull ? rawResources[(wrapper.FileId.Value, wrapper.OffsetInFile.Value)] : ReadCompressedRawResource(wrapper.SqlBytes, decompress), FhirResourceFormat.Json, wrapper.IsMetaSet); @@ -127,7 +126,7 @@ private async Task> ReadResourceWrappers(SqlComma var blobClient = SqlAdlsCient.Container.GetBlobClient(blobName); using var stream = blobClient.OpenRead(); using var reader = new StreamReader(stream); - foreach (var offset in file.Select(_ => _)) + foreach (var offset in file) { reader.DiscardBufferedData(); stream.Position = offset.OffsetInFile; From 24bcfaf805cc7a7641e1acac9ba558120973164a Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 15:49:53 -0800 Subject: [PATCH 082/111] removed redundant select --- tools/Exporter/Program.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/tools/Exporter/Program.cs b/tools/Exporter/Program.cs index 6b261c8762..1fd1d8a3e4 100644 --- a/tools/Exporter/Program.cs +++ b/tools/Exporter/Program.cs @@ -158,7 +158,7 @@ public static void SortedReads(int count, int parall) var loop = 0; foreach (var r in refs.GroupBy(_ => _.FileId)) { - var subSetRefs = r.Select(_ => _).ToList(); + var subSetRefs = r.ToList(); var sw = Stopwatch.StartNew(); var resources = GetRawResourceFromAdls(subSetRefs, true, parall); From 7d5368e8affb89d7ebfd1709af9867f82683f69b Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 16:35:51 -0800 Subject: [PATCH 083/111] check for adls client is null after returning empty --- .../Features/Storage/SqlStoreClient.cs | 12 ++++++------ tools/Exporter/Program.cs | 3 ++- 2 files changed, 8 insertions(+), 7 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index dcffd47253..926d34cac0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -108,18 +108,18 @@ private async Task> ReadResourceWrappers(SqlComma internal static IDictionary<(long FileId, int OffsetInFile), string> GetRawResourcesFromAdls(IReadOnlyList<(long FileId, int OffsetInFile)> resourceRefs) { - if (SqlAdlsCient.Container == null) - { - throw new InvalidOperationException("ADLS container is null."); - } - - var resourceRefsByFile = resourceRefs.GroupBy(_ => _.FileId); var results = new Dictionary<(long FileId, int OffsetInFile), string>(); if (resourceRefs == null || resourceRefs.Count == 0) { return results; } + if (SqlAdlsCient.Container == null) + { + throw new InvalidOperationException("ADLS container is null."); + } + + var resourceRefsByFile = resourceRefs.GroupBy(_ => _.FileId); foreach (var file in resourceRefsByFile) { var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(file.Key); diff --git a/tools/Exporter/Program.cs b/tools/Exporter/Program.cs index 1fd1d8a3e4..2e1f6b17de 100644 --- a/tools/Exporter/Program.cs +++ b/tools/Exporter/Program.cs @@ -65,8 +65,9 @@ public static void Main(string[] args) { _fileSystem.GetFileClient("blobName").OpenRead(); } - catch + catch // Ignore { + return; } var parall = args.Length > 2 ? int.Parse(args[2]) : 8; From 3db2a4d2a581bc26cc46442f0fc808bd8ead36de Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 16:36:42 -0800 Subject: [PATCH 084/111] name typo --- .../Features/Search/SqlServerSearchService.cs | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index 3f25b572f7..c49706af9f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -552,7 +552,7 @@ await _sqlRetryService.ExecuteSql( // add raw resource to search entry var resources = new List(sqlSearchOptions.MaxItemCount); - var rawReaources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); + var rawResources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); foreach (var tmpResource in tmpResources) { if (!clonedSearchOptions.OnlyIds) @@ -560,7 +560,7 @@ await _sqlRetryService.ExecuteSql( var rawResource = new Lazy(() => { var decompressed = tmpResource.SqlBytes.IsNull - ? rawReaources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] + ? rawResources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] : SqlStoreClient.ReadCompressedRawResource(tmpResource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource); _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(tmpResource.Entry.Resource.ResourceSurrogateId), tmpResource.Entry.Resource.ResourceSurrogateId, nameof(tmpResource.Entry.Resource.ResourceTypeName), tmpResource.Entry.Resource.ResourceTypeName, decompressed.Length); if (string.IsNullOrEmpty(decompressed)) From e5f833f4a7e2c6fd8c1d58e53b076b2906c91e81 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 27 Dec 2024 17:12:40 -0800 Subject: [PATCH 085/111] Removed file system --- tools/Exporter/Exporter.csproj | 1 - tools/Exporter/Program.cs | 142 ++++++++++++++++----------------- 2 files changed, 71 insertions(+), 72 deletions(-) diff --git a/tools/Exporter/Exporter.csproj b/tools/Exporter/Exporter.csproj index 3ccc41ca90..daf9b05fc1 100644 --- a/tools/Exporter/Exporter.csproj +++ b/tools/Exporter/Exporter.csproj @@ -6,7 +6,6 @@ Microsoft.Health.Internal.Fhir.Exporter enable true - net6.0 diff --git a/tools/Exporter/Program.cs b/tools/Exporter/Program.cs index 2e1f6b17de..c0e2aeac17 100644 --- a/tools/Exporter/Program.cs +++ b/tools/Exporter/Program.cs @@ -16,7 +16,7 @@ using Azure.Identity; using Azure.Storage.Blobs; using Azure.Storage.Blobs.Specialized; -using Azure.Storage.Files.DataLake; +////using Azure.Storage.Files.DataLake; using Microsoft.AspNetCore.Components.Forms; using Microsoft.Data.SqlClient; using Microsoft.Health.Fhir.Store.Utils; @@ -52,7 +52,7 @@ public static class Program private static Stopwatch _unzip = new Stopwatch(); private static Stopwatch _blob = new Stopwatch(); private static BlobContainerClient _blobContainer; - private static DataLakeFileSystemClient _fileSystem; + ////private static DataLakeFileSystemClient _fileSystem; public static void Main(string[] args) { @@ -60,15 +60,15 @@ public static void Main(string[] args) { var count = args.Length > 1 ? int.Parse(args[1]) : 100; _blobContainer = GetContainer(AdlsUri, AdlsUAMI, AdlsContainerName); - _fileSystem = new DataLakeFileSystemClient(new Uri($"{AdlsUri}/{AdlsContainerName}"), string.IsNullOrEmpty(AdlsUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(AdlsUAMI)); - try - { - _fileSystem.GetFileClient("blobName").OpenRead(); - } - catch // Ignore - { - return; - } + ////_fileSystem = new DataLakeFileSystemClient(new Uri($"{AdlsUri}/{AdlsContainerName}"), string.IsNullOrEmpty(AdlsUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(AdlsUAMI)); + ////try + ////{ + //// _fileSystem.GetFileClient("blobName").OpenRead(); + ////} + ////catch // Ignore + ////{ + //// return; + ////} var parall = args.Length > 2 ? int.Parse(args[2]) : 8; @@ -221,25 +221,25 @@ public static IReadOnlyList GetRawResourceFromAdls(IReadOnlyList<(long F } else { - var resourceRefsByTransaction = resourceRefs.GroupBy(_ => _.FileId); - Parallel.ForEach(resourceRefsByTransaction, new ParallelOptions { MaxDegreeOfParallelism = parall }, (group) => - { - var transactionId = group.Key; - var blobName = GetBlobName(transactionId); - var fileClient = _fileSystem.GetFileClient(blobName); - using var stream = fileClient.OpenRead(); - using var reader = new StreamReader(stream); - foreach (var resourceRef in group) - { - reader.DiscardBufferedData(); - stream.Position = resourceRef.OffsetInFile; - var line = reader.ReadLine(); - lock (results) - { - results.Add(line); - } - } - }); + ////var resourceRefsByTransaction = resourceRefs.GroupBy(_ => _.FileId); + ////Parallel.ForEach(resourceRefsByTransaction, new ParallelOptions { MaxDegreeOfParallelism = parall }, (group) => + ////{ + //// var transactionId = group.Key; + //// var blobName = GetBlobName(transactionId); + //// var fileClient = _fileSystem.GetFileClient(blobName); + //// using var stream = fileClient.OpenRead(); + //// using var reader = new StreamReader(stream); + //// foreach (var resourceRef in group) + //// { + //// reader.DiscardBufferedData(); + //// stream.Position = resourceRef.OffsetInFile; + //// var line = reader.ReadLine(); + //// lock (results) + //// { + //// results.Add(line); + //// } + //// } + ////}); } Source.LogEvent("GetRawResourceFromAdls", "Warn", $"Resources={results.Count}", start); @@ -267,47 +267,47 @@ public static void WriteAndReadAdls(int count, int bufferKB) { GetContainer(AdlsUri, AdlsUAMI, "fhir-hs-new-one-file"); - var fileName = "transaction-353229202.ndjson"; - - var swGlobal = Stopwatch.StartNew(); - - var fileSystem = new DataLakeFileSystemClient(new Uri(AdlsUri), string.IsNullOrEmpty(AdlsUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(AdlsUAMI)); - var fileClient = fileSystem.GetFileClient($"fhir-hs-new-one-file/{fileName}"); - - var offests = new List(); - var offset = 0; - var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); - - var baseLine = string.Concat(Enumerable.Repeat("0123456789", 200)); // 2KB - - using var writeStream = fileClient.OpenWrite(true); - using var writer = new StreamWriter(writeStream); - for (var i = 0; i < count; i++) - { - offests.Add(offset); - var line = $"{offset}\t{baseLine}"; - offset += Encoding.UTF8.GetByteCount(line) + eol; - writer.WriteLine(line); - } - - writer.Flush(); - Console.WriteLine($"ADLS.Write.{count}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); - - swGlobal = Stopwatch.StartNew(); - fileClient = fileSystem.GetFileClient($"testadls/{fileName}"); - using var stream = fileClient.OpenRead(bufferSize: 1024 * bufferKB); - using var reader = new StreamReader(stream); - foreach (var pos in offests) - { - var sw = Stopwatch.StartNew(); - reader.DiscardBufferedData(); - stream.Position = pos; - var line = reader.ReadLine(); - var readOffset = line.Split('\t')[0]; - Console.WriteLine($"ADLS.Read.{count}.buffer={bufferKB}: {sw.Elapsed.TotalMilliseconds} msec (input,read)=({pos},{readOffset})"); - } - - Console.WriteLine($"ADLS.Read.{count}.buffer={bufferKB}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); + ////var fileName = "transaction-353229202.ndjson"; + + ////var swGlobal = Stopwatch.StartNew(); + + ////var fileSystem = new DataLakeFileSystemClient(new Uri(AdlsUri), string.IsNullOrEmpty(AdlsUAMI) ? new InteractiveBrowserCredential() : new ManagedIdentityCredential(AdlsUAMI)); + ////var fileClient = fileSystem.GetFileClient($"fhir-hs-new-one-file/{fileName}"); + + ////var offests = new List(); + ////var offset = 0; + ////var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); + + ////var baseLine = string.Concat(Enumerable.Repeat("0123456789", 200)); // 2KB + + ////using var writeStream = fileClient.OpenWrite(true); + ////using var writer = new StreamWriter(writeStream); + ////for (var i = 0; i < count; i++) + ////{ + //// offests.Add(offset); + //// var line = $"{offset}\t{baseLine}"; + //// offset += Encoding.UTF8.GetByteCount(line) + eol; + //// writer.WriteLine(line); + ////} + + ////writer.Flush(); + ////Console.WriteLine($"ADLS.Write.{count}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); + + ////swGlobal = Stopwatch.StartNew(); + ////fileClient = fileSystem.GetFileClient($"testadls/{fileName}"); + ////using var stream = fileClient.OpenRead(bufferSize: 1024 * bufferKB); + ////using var reader = new StreamReader(stream); + ////foreach (var pos in offests) + ////{ + //// var sw = Stopwatch.StartNew(); + //// reader.DiscardBufferedData(); + //// stream.Position = pos; + //// var line = reader.ReadLine(); + //// var readOffset = line.Split('\t')[0]; + //// Console.WriteLine($"ADLS.Read.{count}.buffer={bufferKB}: {sw.Elapsed.TotalMilliseconds} msec (input,read)=({pos},{readOffset})"); + ////} + + ////Console.WriteLine($"ADLS.Read.{count}.buffer={bufferKB}: total={swGlobal.Elapsed.TotalMilliseconds} msec perLine={swGlobal.Elapsed.TotalMilliseconds / count} msec"); } public static void WriteAndReadBlob(int count, int bufferKB, int parall) From 747e1d94d88ee0087eced703d867289b162fb410 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 29 Dec 2024 16:42:38 -0800 Subject: [PATCH 086/111] Hard delete check for invisible resource --- .../Features/Schema/Migrations/85.diff.sql | 8 ++++++-- .../Features/Schema/Migrations/85.sql | 4 +++- .../Features/Schema/Sql/Sprocs/HardDeleteResource.sql | 4 +++- 3 files changed, 12 insertions(+), 4 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 0698bc4946..921e70cfc5 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -1912,7 +1912,9 @@ BEGIN TRY WHERE ResourceTypeId = @ResourceTypeId AND ResourceId = @ResourceId AND (@KeepCurrentVersion = 0 OR IsHistory = 1) - --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + AND (RawResource IS NULL -- stored in ADLS + OR RawResource <> 0xF -- stored in the database and not already invisible + ) ELSE BEGIN DELETE dbo.Resource @@ -3001,7 +3003,9 @@ BEGIN TRY WHERE ResourceTypeId = @ResourceTypeId AND ResourceId = @ResourceId AND (@KeepCurrentVersion = 0 OR IsHistory = 1) - --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + AND (RawResource IS NULL -- stored in ADLS + OR RawResource <> 0xF -- stored in the database and not already invisible + ) ELSE BEGIN DELETE dbo.Resource diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index f2d16d9277..24919d562a 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -3544,7 +3544,9 @@ BEGIN TRY WHERE ResourceTypeId = @ResourceTypeId AND ResourceId = @ResourceId AND (@KeepCurrentVersion = 0 - OR IsHistory = 1); + OR IsHistory = 1) + AND (RawResource IS NULL + OR RawResource <> 0xF); ELSE BEGIN DELETE dbo.Resource diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql index eb057d70df..a259689b42 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql @@ -42,7 +42,9 @@ BEGIN TRY WHERE ResourceTypeId = @ResourceTypeId AND ResourceId = @ResourceId AND (@KeepCurrentVersion = 0 OR IsHistory = 1) - --AND RawResource <> 0xF -- Cannot check this as resource can be stored in ADLS + AND (RawResource IS NULL -- stored in ADLS + OR RawResource <> 0xF -- stored in the database and not already invisible + ) ELSE BEGIN DELETE dbo.Resource From dad9d90f923b0491edf616adca0ae2837e894c9d Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 31 Dec 2024 17:52:18 -0800 Subject: [PATCH 087/111] hard delete fix --- .../Features/Schema/Migrations/85.diff.sql | 8 ++++---- .../Features/Schema/Migrations/85.sql | 3 ++- .../Features/Schema/Sql/Sprocs/HardDeleteResource.sql | 2 +- 3 files changed, 7 insertions(+), 6 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 921e70cfc5..a1e124676d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -1894,7 +1894,7 @@ BEGIN SET @Mode += ' T='+convert(varchar,@TransactionId) END -DECLARE @Ids TABLE (ResourceSurrogateId bigint NOT NULL, ResourceIdInt bigint NOT NULL) +DECLARE @Ids TABLE (ResourceSurrogateId bigint NOT NULL, ResourceIdInt bigint NULL) DECLARE @IdsDistinct TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL PRIMARY KEY (ResourceTypeId, ResourceIdInt)) DECLARE @RefIdsRaw TABLE (ResourceTypeId smallint NOT NULL, ResourceIdInt bigint NOT NULL) @@ -1947,7 +1947,7 @@ BEGIN TRY BEGIN -- PAGLOCK allows deallocation of empty page without waiting for ghost cleanup DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ResourceWriteClaim B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) - DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceSearchParamTbl B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.ReferenceSearchParamTbl B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B OUTPUT deleted.ReferenceResourceTypeId, deleted.ReferenceResourceIdInt INTO @RefIdsRaw FROM @Ids A INNER LOOP JOIN dbo.ResourceReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) @@ -1969,7 +1969,7 @@ BEGIN TRY END END END - DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) @@ -3059,7 +3059,7 @@ BEGIN TRY END END END - DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index 24919d562a..28bc58d9aa 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -3648,7 +3648,8 @@ BEGIN TRY FROM @Ids AS A INNER LOOP JOIN dbo.StringReferenceSearchParams AS B WITH (INDEX (1), FORCESEEK, PAGLOCK) - ON B.ResourceSurrogateId = A.ResourceSurrogateId + ON B.ResourceTypeId = @ResourceTypeId + AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1); DELETE B FROM @Ids AS A diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql index a259689b42..24dd4ef06d 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql @@ -98,7 +98,7 @@ BEGIN TRY END END END - DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) + DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringReferenceSearchParams B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.TokenText B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) DELETE FROM B FROM @Ids A INNER LOOP JOIN dbo.StringSearchParam B WITH (INDEX = 1, FORCESEEK, PAGLOCK) ON B.ResourceTypeId = @ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId OPTION (MAXDOP 1) From 890d5caf2fb9354f892850783325da8f235fb61a Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 2 Jan 2025 11:18:59 -0800 Subject: [PATCH 088/111] move alter inside try/catch --- .../Features/Schema/Migrations/85.diff.sql | 316 +++++++++--------- .../SqlServerSchemaUpgradeTests.cs | 2 +- 2 files changed, 156 insertions(+), 162 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index a1e124676d..0cc2423c2f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -362,63 +362,6 @@ END CATCH COMMIT TRANSACTION END GO -CREATE OR ALTER VIEW dbo.Resource -AS -SELECT A.ResourceTypeId - ,A.ResourceSurrogateId - ,ResourceId - ,A.ResourceIdInt - ,Version - ,IsHistory - ,IsDeleted - ,RequestMethod - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,TransactionId - ,HistoryTransactionId - ,FileId - ,OffsetInFile - FROM dbo.CurrentResources A - LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt -UNION ALL -SELECT A.ResourceTypeId - ,A.ResourceSurrogateId - ,ResourceId - ,A.ResourceIdInt - ,Version - ,IsHistory - ,IsDeleted - ,RequestMethod - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,TransactionId - ,HistoryTransactionId - ,FileId - ,OffsetInFile - FROM dbo.HistoryResources A - LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId - LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt -UNION ALL -SELECT ResourceTypeId - ,ResourceSurrogateId - ,ResourceId - ,NULL - ,Version - ,IsHistory - ,IsDeleted - ,RequestMethod - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,TransactionId - ,HistoryTransactionId - ,NULL - ,NULL - FROM dbo.ResourceTbl -GO CREATE OR ALTER VIEW dbo.CurrentResource AS SELECT A.ResourceTypeId @@ -568,6 +511,7 @@ BEGIN SELECT ResourceTypeId, ResourceSurrogateId, ResourceIdInt, Version, IsDeleted, RequestMethod, IsRawResourceMetaSet, SearchParamHash, TransactionId, HistoryTransactionId, FileId, OffsetInFile FROM Inserted WHERE IsHistory = 1 + AND ResourceIdInt IS NOT NULL END GO CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE @@ -691,13 +635,15 @@ END COMMIT TRANSACTION END GO -BEGIN TRANSACTION -- update ReferenceSearchParamList -GO -DROP PROCEDURE CaptureResourceIdsForChanges -DROP PROCEDURE MergeResources -DROP PROCEDURE UpdateResourceSearchParams -DROP TYPE ReferenceSearchParamList -GO +BEGIN TRY + BEGIN TRANSACTION -- update ReferenceSearchParamList + + DROP PROCEDURE CaptureResourceIdsForChanges + DROP PROCEDURE MergeResources + DROP PROCEDURE UpdateResourceSearchParams + DROP TYPE ReferenceSearchParamList + + EXECUTE(' CREATE TYPE dbo.ReferenceSearchParamList AS TABLE ( ResourceTypeId smallint NOT NULL @@ -710,7 +656,8 @@ CREATE TYPE dbo.ReferenceSearchParamList AS TABLE UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId) ) -GO +') + EXECUTE(' CREATE PROCEDURE dbo.CaptureResourceIdsForChanges @Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY AS set nocount on @@ -720,9 +667,9 @@ INSERT INTO dbo.ResourceChangeData SELECT ResourceId, ResourceTypeId, Version, CASE WHEN IsDeleted = 1 THEN 2 WHEN Version > 1 THEN 1 ELSE 0 END FROM (SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @Resources UNION ALL SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @ResourcesLake) A WHERE IsHistory = 0 -GO --- The following 2 procs and trigger are special for data movement -GO +') + -- The following 2 procs and trigger are special for data movement + EXECUTE(' CREATE PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT ,@Resources dbo.ResourceList READONLY -- TODO: Remove after deployment @@ -746,7 +693,7 @@ AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),'Input=Empty') + ,@Mode varchar(200) = isnull((SELECT ''RT=[''+convert(varchar,min(ResourceTypeId))+'',''+convert(varchar,max(ResourceTypeId))+''] Sur=[''+convert(varchar,min(ResourceSurrogateId))+'',''+convert(varchar,max(ResourceSurrogateId))+''] V=''+convert(varchar,max(Version))+'' Rows=''+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),''Input=Empty'') ,@ResourceRows int ,@InsertRows int ,@DeletedIdMap int @@ -967,15 +914,15 @@ BEGIN TRY SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @ResourceRows - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@ResourceRows,@Text=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@ResourceRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st - IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation - OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + IF error_number() IN (2601, 2627) AND error_message() LIKE ''%''''dbo.ResourceIdIntMap''''%'' -- pk violation + OR error_number() = 547 AND error_message() LIKE ''%DELETE%'' -- reference violation on DELETE BEGIN DELETE FROM @Ids DELETE FROM @InputRefIds @@ -991,7 +938,9 @@ BEGIN CATCH ELSE THROW END CATCH -GO +') + + EXECUTE(' CREATE PROCEDURE dbo.MergeResources -- This stored procedure can be used for: -- 1. Ordinary put with single version per resource in input @@ -1032,8 +981,8 @@ DECLARE @st datetime = getUTCdate() ,@CurrentRows int ,@DeletedIdMap int -DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),'Input=Empty') -SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') +DECLARE @Mode varchar(200) = isnull((SELECT ''RT=[''+convert(varchar,min(ResourceTypeId))+'',''+convert(varchar,max(ResourceTypeId))+''] Sur=[''+convert(varchar,min(ResourceSurrogateId))+'',''+convert(varchar,max(ResourceSurrogateId))+''] V=''+convert(varchar,max(Version))+'' Rows=''+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),''Input=Empty'') +SET @Mode += '' E=''+convert(varchar,@RaiseExceptionOnConflict)+'' CC=''+convert(varchar,@IsResourceChangeCaptureEnabled)+'' IT=''+convert(varchar,@InitialTranCount)+'' T=''+isnull(convert(varchar,@TransactionId),''NULL'') SET @AffectedRows = 0 @@ -1180,15 +1129,15 @@ BEGIN TRY DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) - IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 + IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = ''MergeResources.NoTransaction.IsEnabled''),0) = 0 SET @SingleTransaction = 1 - SET @Mode += ' ST='+convert(varchar,@SingleTransaction) + SET @Mode += '' ST=''+convert(varchar,@SingleTransaction) -- perform retry check in transaction to hold locks IF @InitialTranCount = 0 BEGIN - IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them + IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don''t need them FROM @ResourcesWithIds A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 ) @@ -1211,7 +1160,7 @@ BEGIN TRY END END - SET @Mode += ' R='+convert(varchar,@IsRetry) + SET @Mode += '' R=''+convert(varchar,@IsRetry) IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION @@ -1221,12 +1170,12 @@ BEGIN TRY ( ResourceTypeId, SurrogateId, Version, KeepHistory, PreviousVersion, PreviousSurrogateId ) SELECT A.ResourceTypeId, A.ResourceSurrogateId, A.Version, A.KeepHistory, B.Version, B.ResourceSurrogateId FROM (SELECT TOP (@DummyTop) * FROM @ResourcesWithIds WHERE HasVersionToCompare = 1) A - LEFT OUTER JOIN dbo.CurrentResources B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. - ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt + LEFT OUTER JOIN dbo.CurrentResource B -- WITH (UPDLOCK, HOLDLOCK) These locking hints cause deadlocks and are not needed. Racing might lead to tries to insert dups in unique index (with version key), but it will fail anyway, and in no case this will cause incorrect data saved. + ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <= PreviousVersion) - THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 + THROW 50409, ''Resource has been recently updated or added, please compare the resource content in code for any duplicate updates'', 1 INSERT INTO @PreviousSurrogateIds SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory @@ -1240,7 +1189,7 @@ BEGIN TRY WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) SET @AffectedRows += @@rowcount - IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) + IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = ''InvisibleHistory.IsEnabled'' AND Number = 0) UPDATE dbo.Resource SET IsHistory = 1 ,RawResource = 0xF -- "invisible" value @@ -1316,7 +1265,7 @@ BEGIN TRY DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount - --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' + --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Info'',@Start=@st,@Rows=@AffectedRows,@Text=''Old rows'' END INSERT INTO dbo.ResourceIdIntMap @@ -1587,16 +1536,16 @@ BEGIN TRY IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows,@Text=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@AffectedRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st - IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation - OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + IF error_number() IN (2601, 2627) AND error_message() LIKE ''%''''dbo.ResourceIdIntMap''''%'' -- pk violation + OR error_number() = 547 AND error_message() LIKE ''%DELETE%'' -- reference violation on DELETE BEGIN DELETE FROM @ResourcesWithIds DELETE FROM @ReferenceSearchParamsWithIds @@ -1615,13 +1564,19 @@ BEGIN CATCH GOTO RetryResourceIdIntMapLogic END ELSE - IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') - THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE ''%''''dbo.Resource%'' OR error_message() LIKE ''%''''dbo.CurrentResources%'' OR error_message() LIKE ''%''''dbo.HistoryResources%'' OR error_message() LIKE ''%''''dbo.RawResources''''%'') + THROW 50409, ''Resource has been recently updated or added, please compare the resource content in code for any duplicate updates'', 1; ELSE THROW END CATCH -GO -COMMIT TRANSACTION +') + + COMMIT TRANSACTION +END TRY +BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + THROW +END CATCH GO -- Special versions of procedures for data movement GO @@ -2345,12 +2300,8 @@ BEGIN TRY END EXECUTE dbo.LogEvent @Process=@Process,@Status='End' -END TRY -BEGIN CATCH - EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; - THROW -END CATCH -GO + + EXECUTE(' ALTER VIEW dbo.ReferenceSearchParam AS SELECT A.ResourceTypeId @@ -2373,7 +2324,10 @@ SELECT ResourceTypeId ,NULL ,IsResourceRef FROM dbo.StringReferenceSearchParams -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='ReferenceSearchParam',@Action='Alter' + + EXECUTE(' ALTER VIEW dbo.Resource AS SELECT A.ResourceTypeId @@ -2413,7 +2367,10 @@ SELECT A.ResourceTypeId FROM dbo.HistoryResources A LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='Resource',@Action='Alter' + + EXECUTE(' ALTER VIEW dbo.CurrentResource AS SELECT A.ResourceTypeId @@ -2434,7 +2391,10 @@ SELECT A.ResourceTypeId FROM dbo.CurrentResources A LEFT OUTER JOIN dbo.RawResources B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId LEFT OUTER JOIN dbo.ResourceIdIntMap C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = A.ResourceIdInt -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='CurrentResource',@Action='Alter' + + EXECUTE(' ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT AS BEGIN @@ -2456,7 +2416,10 @@ BEGIN FROM Inserted WHERE IsHistory = 1 END -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='ResourceIns',@Action='Alter' + + EXECUTE(' ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE AS BEGIN @@ -2526,7 +2489,7 @@ BEGIN END IF NOT UPDATE(IsHistory) - RAISERROR('Generic updates are not supported via Resource view',18,127) + RAISERROR(''Generic updates are not supported via Resource view'',18,127) DELETE FROM A FROM dbo.CurrentResources A @@ -2538,7 +2501,10 @@ BEGIN FROM Inserted WHERE IsHistory = 1 END -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='ResourceUpd',@Action='Alter' + + EXECUTE(' ALTER TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE AS BEGIN @@ -2554,14 +2520,17 @@ BEGIN FROM dbo.RawResources A WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) END -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='ResourceDel',@Action='Alter' + + EXECUTE(' ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY AS -- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated set nocount on DECLARE @st datetime = getUTCdate() - ,@SP varchar(100) = 'GetResourceVersions' - ,@Mode varchar(100) = 'Rows='+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) + ,@SP varchar(100) = ''GetResourceVersions'' + ,@Mode varchar(100) = ''Rows=''+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) ,@DummyTop bigint = 9223372036854775807 BEGIN TRY @@ -2590,19 +2559,22 @@ BEGIN TRY OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st; THROW END CATCH -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='GetResourceVersions',@Action='Alter' + + EXECUTE(' ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY AS set nocount on DECLARE @st datetime = getUTCdate() - ,@SP varchar(100) = 'GetResources' + ,@SP varchar(100) = ''GetResources'' ,@InputRows int ,@NotNullVersionExists bit ,@NullVersionExists bit @@ -2611,7 +2583,7 @@ DECLARE @st datetime = getUTCdate() SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys -DECLARE @Mode varchar(100) = 'RT=['+convert(varchar,@MinRT)+','+convert(varchar,@MaxRT)+'] Cnt='+convert(varchar,@InputRows)+' NNVE='+convert(varchar,@NotNullVersionExists)+' NVE='+convert(varchar,@NullVersionExists) +DECLARE @Mode varchar(100) = ''RT=[''+convert(varchar,@MinRT)+'',''+convert(varchar,@MaxRT)+''] Cnt=''+convert(varchar,@InputRows)+'' NNVE=''+convert(varchar,@NotNullVersionExists)+'' NVE=''+convert(varchar,@NullVersionExists) BEGIN TRY IF @NotNullVersionExists = 1 @@ -2683,14 +2655,17 @@ BEGIN TRY LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId OPTION (MAXDOP 1) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st; THROW END CATCH -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='GetResources',@Action='Alter' + + EXECUTE(' ALTER PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT ,@Resources dbo.ResourceList READONLY -- TODO: Remove after deployment @@ -2714,7 +2689,7 @@ AS set nocount on DECLARE @st datetime = getUTCdate() ,@SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),'Input=Empty') + ,@Mode varchar(200) = isnull((SELECT ''RT=[''+convert(varchar,min(ResourceTypeId))+'',''+convert(varchar,max(ResourceTypeId))+''] Sur=[''+convert(varchar,min(ResourceSurrogateId))+'',''+convert(varchar,max(ResourceSurrogateId))+''] V=''+convert(varchar,max(Version))+'' Rows=''+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources) A),''Input=Empty'') ,@ResourceRows int ,@InsertRows int ,@DeletedIdMap int @@ -2934,15 +2909,15 @@ BEGIN TRY SET @FailedResources = (SELECT count(*) FROM @Resources) + (SELECT count(*) FROM @ResourcesLake) - @ResourceRows - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@ResourceRows,@Text=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@ResourceRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st - IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation - OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + IF error_number() IN (2601, 2627) AND error_message() LIKE ''%''''dbo.ResourceIdIntMap''''%'' -- pk violation + OR error_number() = 547 AND error_message() LIKE ''%DELETE%'' -- reference violation on DELETE BEGIN DELETE FROM @Ids DELETE FROM @InputRefIds @@ -2958,7 +2933,10 @@ BEGIN CATCH ELSE THROW END CATCH -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='UpdateResourceSearchParams',@Action='Alter' + + EXECUTE(' ALTER PROCEDURE dbo.HardDeleteResource @ResourceTypeId smallint ,@ResourceId varchar(64) @@ -2968,7 +2946,7 @@ ALTER PROCEDURE dbo.HardDeleteResource AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) + ,@Mode varchar(200) = ''RT=''+convert(varchar,@ResourceTypeId)+'' R=''+@ResourceId+'' V=''+convert(varchar,@KeepCurrentVersion) ,@st datetime = getUTCdate() ,@TransactionId bigint ,@DeletedIdMap int = 0 @@ -2977,12 +2955,12 @@ DECLARE @SP varchar(100) = object_name(@@procid) IF @IsResourceChangeCaptureEnabled = 1 SET @MakeResourceInvisible = 1 -SET @Mode += ' I='+convert(varchar,@MakeResourceInvisible) +SET @Mode += '' I=''+convert(varchar,@MakeResourceInvisible) IF @MakeResourceInvisible = 1 BEGIN EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT - SET @Mode += ' T='+convert(varchar,@TransactionId) + SET @Mode += '' T=''+convert(varchar,@TransactionId) END DECLARE @Ids TABLE (ResourceSurrogateId bigint NOT NULL, ResourceIdInt bigint NOT NULL) @@ -3080,13 +3058,13 @@ BEGIN TRY IF @MakeResourceInvisible = 1 EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st - IF error_number() = 547 AND error_message() LIKE '%DELETE%'-- reference violation on DELETE + IF error_number() = 547 AND error_message() LIKE ''%DELETE%''-- reference violation on DELETE BEGIN DELETE FROM @Ids DELETE FROM @RefIdsRaw @@ -3096,7 +3074,10 @@ BEGIN CATCH ELSE THROW END CATCH -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='HardDeleteResource',@Action='Alter' + + EXECUTE(' ALTER PROCEDURE dbo.MergeResources -- This stored procedure can be used for: -- 1. Ordinary put with single version per resource in input @@ -3137,8 +3118,8 @@ DECLARE @st datetime = getUTCdate() ,@CurrentRows int ,@DeletedIdMap int -DECLARE @Mode varchar(200) = isnull((SELECT 'RT=['+convert(varchar,min(ResourceTypeId))+','+convert(varchar,max(ResourceTypeId))+'] Sur=['+convert(varchar,min(ResourceSurrogateId))+','+convert(varchar,max(ResourceSurrogateId))+'] V='+convert(varchar,max(Version))+' Rows='+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),'Input=Empty') -SET @Mode += ' E='+convert(varchar,@RaiseExceptionOnConflict)+' CC='+convert(varchar,@IsResourceChangeCaptureEnabled)+' IT='+convert(varchar,@InitialTranCount)+' T='+isnull(convert(varchar,@TransactionId),'NULL') +DECLARE @Mode varchar(200) = isnull((SELECT ''RT=[''+convert(varchar,min(ResourceTypeId))+'',''+convert(varchar,max(ResourceTypeId))+''] Sur=[''+convert(varchar,min(ResourceSurrogateId))+'',''+convert(varchar,max(ResourceSurrogateId))+''] V=''+convert(varchar,max(Version))+'' Rows=''+convert(varchar,count(*)) FROM (SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @Resources UNION ALL SELECT ResourceTypeId, ResourceSurrogateId, Version FROM @ResourcesLake) A),''Input=Empty'') +SET @Mode += '' E=''+convert(varchar,@RaiseExceptionOnConflict)+'' CC=''+convert(varchar,@IsResourceChangeCaptureEnabled)+'' IT=''+convert(varchar,@InitialTranCount)+'' T=''+isnull(convert(varchar,@TransactionId),''NULL'') SET @AffectedRows = 0 @@ -3285,15 +3266,15 @@ BEGIN TRY DECLARE @PreviousSurrogateIds AS TABLE (TypeId smallint NOT NULL, SurrogateId bigint NOT NULL PRIMARY KEY (TypeId, SurrogateId), KeepHistory bit) - IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = 'MergeResources.NoTransaction.IsEnabled'),0) = 0 + IF @SingleTransaction = 0 AND isnull((SELECT Number FROM dbo.Parameters WHERE Id = ''MergeResources.NoTransaction.IsEnabled''),0) = 0 SET @SingleTransaction = 1 - SET @Mode += ' ST='+convert(varchar,@SingleTransaction) + SET @Mode += '' ST=''+convert(varchar,@SingleTransaction) -- perform retry check in transaction to hold locks IF @InitialTranCount = 0 BEGIN - IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don't need them + IF EXISTS (SELECT * -- This extra statement avoids putting range locks when we don''t need them FROM @ResourcesWithIds A JOIN dbo.Resource B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId WHERE B.IsHistory = 0 ) @@ -3316,7 +3297,7 @@ BEGIN TRY END END - SET @Mode += ' R='+convert(varchar,@IsRetry) + SET @Mode += '' R=''+convert(varchar,@IsRetry) IF @SingleTransaction = 1 AND @@trancount = 0 BEGIN TRANSACTION @@ -3331,7 +3312,7 @@ BEGIN TRY OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) IF @RaiseExceptionOnConflict = 1 AND EXISTS (SELECT * FROM @ResourceInfos WHERE PreviousVersion IS NOT NULL AND Version <= PreviousVersion) - THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1 + THROW 50409, ''Resource has been recently updated or added, please compare the resource content in code for any duplicate updates'', 1 INSERT INTO @PreviousSurrogateIds SELECT ResourceTypeId, PreviousSurrogateId, KeepHistory @@ -3345,7 +3326,7 @@ BEGIN TRY WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1) SET @AffectedRows += @@rowcount - IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = 'InvisibleHistory.IsEnabled' AND Number = 0) + IF @IsResourceChangeCaptureEnabled = 1 AND NOT EXISTS (SELECT * FROM dbo.Parameters WHERE Id = ''InvisibleHistory.IsEnabled'' AND Number = 0) UPDATE dbo.Resource SET IsHistory = 1 ,RawResource = 0xF -- "invisible" value @@ -3419,7 +3400,7 @@ BEGIN TRY DELETE FROM dbo.TokenNumberNumberCompositeSearchParam WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId) SET @AffectedRows += @@rowcount - --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Start=@st,@Rows=@AffectedRows,@Text='Old rows' + --EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Info'',@Start=@st,@Rows=@AffectedRows,@Text=''Old rows'' END INSERT INTO dbo.ResourceIdIntMap @@ -3690,16 +3671,16 @@ BEGIN TRY IF @InitialTranCount = 0 AND @@trancount > 0 COMMIT TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@AffectedRows,@Text=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@AffectedRows,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @InitialTranCount = 0 AND @@trancount > 0 ROLLBACK TRANSACTION IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st - IF error_number() IN (2601, 2627) AND error_message() LIKE '%''dbo.ResourceIdIntMap''%' -- pk violation - OR error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + IF error_number() IN (2601, 2627) AND error_message() LIKE ''%''''dbo.ResourceIdIntMap''''%'' -- pk violation + OR error_number() = 547 AND error_message() LIKE ''%DELETE%'' -- reference violation on DELETE BEGIN DELETE FROM @ResourcesWithIds DELETE FROM @ReferenceSearchParamsWithIds @@ -3718,17 +3699,20 @@ BEGIN CATCH GOTO RetryResourceIdIntMapLogic END ELSE - IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE '%''dbo.Resource%' OR error_message() LIKE '%''dbo.CurrentResources%' OR error_message() LIKE '%''dbo.HistoryResources%' OR error_message() LIKE '%''dbo.RawResources''%') - THROW 50409, 'Resource has been recently updated or added, please compare the resource content in code for any duplicate updates', 1; + IF @RaiseExceptionOnConflict = 1 AND error_number() IN (2601, 2627) AND (error_message() LIKE ''%''''dbo.Resource%'' OR error_message() LIKE ''%''''dbo.CurrentResources%'' OR error_message() LIKE ''%''''dbo.HistoryResources%'' OR error_message() LIKE ''%''''dbo.RawResources''''%'') + THROW 50409, ''Resource has been recently updated or added, please compare the resource content in code for any duplicate updates'', 1; ELSE THROW END CATCH -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='MergeResources',@Action='Alter' + + EXECUTE(' ALTER PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId bigint, @AffectedRows int = NULL OUT AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId) + ,@Mode varchar(100) = ''T=''+convert(varchar,@TransactionId) ,@st datetime ,@Rows int ,@DeletedIdMap int @@ -3747,7 +3731,7 @@ BEGIN TRY FROM dbo.Resource A WHERE HistoryTransactionId = @TransactionId -- requires updated statistics SET @Rows = @@rowcount - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@Rows + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Run'',@Target=''Resource'',@Action=''Delete'',@Start=@st,@Rows=@Rows SET @AffectedRows += @Rows SET @st = getUTCdate() @@ -3768,20 +3752,20 @@ BEGIN TRY SET @DeletedIdMap = @@rowcount END END - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Run'',@Target=''ResourceIdIntMap'',@Action=''Delete'',@Start=@st,@Rows=@DeletedIdMap END COMMIT TRANSACTION SET @st = getUTCdate() UPDATE dbo.Resource SET TransactionId = NULL WHERE TransactionId = @TransactionId - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Target='Resource',@Action='Update',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Target=''Resource'',@Action=''Update'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error' - IF error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'' + IF error_number() = 547 AND error_message() LIKE ''%DELETE%'' -- reference violation on DELETE BEGIN DELETE FROM @Ids GOTO Retry @@ -3789,17 +3773,20 @@ BEGIN CATCH ELSE THROW END CATCH -GO + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='MergeResourcesDeleteInvisibleHistory',@Action='Alter' + + EXECUTE(' ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 1, @IncludeDeleted bit = 1 AS set nocount on -DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' - ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') - +' S='+isnull(convert(varchar,@StartId),'NULL') - +' E='+isnull(convert(varchar,@EndId),'NULL') - +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') - +' HI='+isnull(convert(varchar,@IncludeHistory),'NULL') - +' DE='+isnull(convert(varchar,@IncludeDeleted),'NULL') +DECLARE @SP varchar(100) = ''GetResourcesByTypeAndSurrogateIdRange'' + ,@Mode varchar(100) = ''RT=''+isnull(convert(varchar,@ResourceTypeId),''NULL'') + +'' S=''+isnull(convert(varchar,@StartId),''NULL'') + +'' E=''+isnull(convert(varchar,@EndId),''NULL'') + +'' GE=''+isnull(convert(varchar,@GlobalEndId),''NULL'') + +'' HI=''+isnull(convert(varchar,@IncludeHistory),''NULL'') + +'' DE=''+isnull(convert(varchar,@IncludeDeleted),''NULL'') ,@st datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 ,@Rows int @@ -3861,11 +3848,18 @@ BEGIN TRY AND (IsDeleted = 0 OR @IncludeDeleted = 1) OPTION (MAXDOP 1, LOOP JOIN) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error''; + THROW +END CATCH + ') + EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Target='GetResourcesByTypeAndSurrogateIdRange',@Action='Alter' +END TRY +BEGIN CATCH + EXECUTE dbo.LogEvent @Process=@Process,@Status='Error'; THROW END CATCH GO diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs index f99cd3b1ff..b0c3949ddf 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.Integration/Persistence/SqlServerSchemaUpgradeTests.cs @@ -285,7 +285,7 @@ private async Task CompareDatabaseSchemas(string databaseName1, string d { //// Our home grown SQL schema generator does not understand that statements can be formatted differently but contain identical SQL //// Skipping some objects - var objectsToSkip = new[] { "GetResourceSearchParamStats", "MergeResourcesAdvanceTransactionVisibility", "DequeueJob", "DisableIndexes", "GetResourceVersions", "CleanupEventLog", "InitDefrag", "EnqueueJobs", "GetResourceSurrogateIdRanges", "GetCommandsForRebuildIndexes", "GetIndexCommands", "SwitchPartitionsIn", "SwitchPartitionsOut" }.ToList(); + var objectsToSkip = new[] { "GetResourceSearchParamStats", "DequeueJob", "DisableIndexes", "GetResourceVersions", "EnqueueJobs", "GetResourceSurrogateIdRanges", "GetCommandsForRebuildIndexes", "GetIndexCommands", "SwitchPartitionsIn", "SwitchPartitionsOut" }.ToList(); objectsToSkip.Add("PartitionFunction_ResourceChangeData_Timestamp"); // definition is not predictable as it has start time component if (schemaDifference.SourceObject != null && objectsToSkip.Any(_ => schemaDifference.SourceObject.Name.ToString().Contains(_))) { From d00ee7d599756113440885f09ce211c142f5f94e Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 2 Jan 2025 16:09:32 -0800 Subject: [PATCH 089/111] Added ResourceTbl to update trigger --- .../Features/Schema/Migrations/85.diff.sql | 24 +++++++++++++++++++ 1 file changed, 24 insertions(+) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 0cc2423c2f..55fb264bb7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -431,6 +431,14 @@ AS BEGIN IF UPDATE(IsDeleted) AND UPDATE(RawResource) AND UPDATE(SearchParamHash) AND UPDATE(HistoryTransactionId) AND NOT UPDATE(IsHistory) -- hard delete resource BEGIN + UPDATE B + SET IsDeleted = A.IsDeleted + ,SearchParamHash = A.SearchParamHash + ,HistoryTransactionId = A.HistoryTransactionId + ,RawResource = A.RawResource + FROM Inserted A + JOIN dbo.ResourceTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + UPDATE B SET RawResource = A.RawResource FROM Inserted A @@ -455,6 +463,12 @@ BEGIN IF UPDATE(SearchParamHash) AND NOT UPDATE(IsHistory) -- reindex BEGIN + UPDATE B + SET SearchParamHash = A.SearchParamHash + FROM Inserted A + JOIN dbo.ResourceTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + WHERE A.IsHistory = 0 + UPDATE B SET SearchParamHash = A.SearchParamHash FROM Inserted A @@ -466,6 +480,11 @@ BEGIN IF UPDATE(TransactionId) AND NOT UPDATE(IsHistory) -- cleanup trans BEGIN + UPDATE B + SET TransactionId = A.TransactionId + FROM Inserted A + JOIN dbo.ResourceTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + UPDATE B SET TransactionId = A.TransactionId FROM Inserted A @@ -481,6 +500,11 @@ BEGIN IF UPDATE(RawResource) -- invisible records BEGIN + UPDATE B + SET RawResource = A.RawResource + FROM Inserted A + JOIN dbo.ResourceTbl B ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId + UPDATE B SET RawResource = A.RawResource FROM Inserted A From 7212ebc41821838509e89696df919c37466f6b9f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 2 Jan 2025 16:37:21 -0800 Subject: [PATCH 090/111] Added diag --- tools/PerfTester/App.config | 15 ++- tools/PerfTester/Program.cs | 226 ++++++++++++++++++++++++++++++++++-- 2 files changed, 227 insertions(+), 14 deletions(-) diff --git a/tools/PerfTester/App.config b/tools/PerfTester/App.config index ff7e939433..8248d993cf 100644 --- a/tools/PerfTester/App.config +++ b/tools/PerfTester/App.config @@ -7,7 +7,7 @@ - + @@ -22,8 +22,11 @@ - - + + + @@ -31,10 +34,10 @@ - + - - + + diff --git a/tools/PerfTester/Program.cs b/tools/PerfTester/Program.cs index 79116e0829..13f4a8608d 100644 --- a/tools/PerfTester/Program.cs +++ b/tools/PerfTester/Program.cs @@ -64,6 +64,12 @@ public static void Main() DumpResourceIds(); + if (_callType == "Diag") + { + Diag(); + return; + } + if (_callType == "GetDate" || _callType == "LogEvent") { Console.WriteLine($"Start at {DateTime.UtcNow.ToString("s")}"); @@ -106,6 +112,76 @@ public static void Main() } } + private static void Diag() + { + Console.WriteLine($"Diag: start at {DateTime.UtcNow.ToString("s")}"); + var container = GetContainer(_ndjsonStorageConnectionString, _ndjsonStorageUri, _ndjsonStorageUAMI, _ndjsonStorageContainerName); + var swTotal = Stopwatch.StartNew(); + var patients = GetResourceIds("Patient").Select(_ => _.ResourceId).OrderBy(_ => RandomNumberGenerator.GetInt32((int)1e9)).ToList(); + Console.WriteLine($"Diag: read patient ids = {patients.Count} in {(int)swTotal.Elapsed.TotalSeconds} sec."); + swTotal = Stopwatch.StartNew(); + var observations = GetResourceIds("Observation").Select(_ => _.ResourceId).OrderBy(_ => RandomNumberGenerator.GetInt32((int)1e9)).Take(100000).ToList(); + Console.WriteLine($"Diag: read observation ids = {observations.Count} in {(int)swTotal.Elapsed.TotalSeconds} sec."); + var loop = 0; + var observationIndex = 0; + var patientIndex = 0; + var swReport = Stopwatch.StartNew(); + swTotal = Stopwatch.StartNew(); + var observationEnumerator = GetLinesInBlobs(container, "Observation").GetEnumerator(); + while (true) + { + var id = observations[observationIndex++]; + var sw = Stopwatch.StartNew(); + var status = GetResource("Observation", id); + _store.TryLogEvent("Diag.Get.Observation", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec status={status} id={id}", null, CancellationToken.None).Wait(); + + id = observations[observationIndex++]; + var json = observationEnumerator.MoveNext() ? observationEnumerator.Current : throw new ArgumentException("obervation list is too small"); + ParseJson(ref json, id); // replace id in json + sw = Stopwatch.StartNew(); + status = PutResource(json, "Observation", id); + _store.TryLogEvent("Diag.Update.Observation", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec status={status} id={id}", null, CancellationToken.None).Wait(); + + id = Guid.NewGuid().ToString(); + json = observationEnumerator.MoveNext() ? observationEnumerator.Current : throw new ArgumentException("obervation list is too small"); + ParseJson(ref json, id); // replace id in json + sw = Stopwatch.StartNew(); + status = PutResource(json, "Observation", id); + _store.TryLogEvent("Diag.Create.Observation", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec status={status} id={id}", null, CancellationToken.None).Wait(); + + id = observations[observationIndex++]; + DeleteResource("Observation", id, true); + + id = observations[observationIndex++]; + DeleteResource("Observation", id, false); + + id = observations[observationIndex++]; + UpdateSearchParam(id); + + id = patients[patientIndex++]; + GetObservationsForPatient(id); + + id = patients[patientIndex++]; + GetPatientRevIncludeObservations(id); + + if (swReport.Elapsed.TotalSeconds > _reportingPeriodSec) + { + lock (swReport) + { + if (swReport.Elapsed.TotalSeconds > _reportingPeriodSec) + { + Console.WriteLine($"Diag: loops={loop} elapsed={(int)swTotal.Elapsed.TotalSeconds} sec"); + swReport.Restart(); + } + } + } + + Thread.Sleep(5000); + + loop++; + } + } + private static ReadOnlyList GetRandomTransactionIds() { var sw = Stopwatch.StartNew(); @@ -197,7 +273,7 @@ private static void ExecuteParallelHttpPuts() var resources = 0; long sumLatency = 0; var singleId = Guid.NewGuid().ToString(); - BatchExtensions.ExecuteInParallelBatches(GetLinesInBlobs(sourceContainer), _threads, 1, (thread, lineItem) => + BatchExtensions.ExecuteInParallelBatches(GetLinesInBlobs(sourceContainer, _nameFilter), _threads, 1, (thread, lineItem) => { if (Interlocked.Read(ref calls) >= _calls) { @@ -517,7 +593,7 @@ private static void DumpResourceIds() var container = GetContainer(); using var stream = container.GetBlockBlobClient(_storageBlobName).OpenWrite(true); using var writer = new StreamWriter(stream); - foreach (var resourceId in GetResourceIds()) + foreach (var resourceId in GetResourceIds(_nameFilter)) { lines++; writer.WriteLine($"{resourceId.ResourceTypeId}\t{resourceId.ResourceId}"); @@ -540,16 +616,16 @@ private static void DumpResourceIds() } // cannot use sqlRetryService as I need IEnumerable - private static IEnumerable<(short ResourceTypeId, string ResourceId)> GetResourceIds() + private static IEnumerable<(short ResourceTypeId, string ResourceId)> GetResourceIds(string nameFilter) { using var conn = new SqlConnection(_connectionString); conn.Open(); using var cmd = new SqlCommand("SELECT ResourceTypeId FROM dbo.ResourceType WHERE Name = @Name", conn); - cmd.Parameters.AddWithValue("@Name", _nameFilter); + cmd.Parameters.AddWithValue("@Name", nameFilter); var ret = cmd.ExecuteScalar(); if (ret == DBNull.Value) { - using var cmd2 = new SqlCommand("SELECT ResourceTypeId, ResourceId FROM dbo.Resource WHERE IsHistory = 0", conn); // no need to sort to simulate random access + using var cmd2 = new SqlCommand("SELECT ResourceTypeId, ResourceId FROM dbo.Resource WHERE IsHistory = 0 AND IsDeleted = 0", conn); // no need to sort to simulate random access cmd2.CommandTimeout = 0; using var reader = cmd2.ExecuteReader(); while (reader.Read()) @@ -560,7 +636,7 @@ private static void DumpResourceIds() else { var resourceTypeId = (short)ret; - using var cmd2 = new SqlCommand("SELECT ResourceTypeId, ResourceId FROM dbo.Resource WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) WHERE IsHistory = 0 AND ResourceTypeId = @ResourceTypeId ORDER BY ResourceTypeId, ResourceId OPTION (MAXDOP 1)", conn); + using var cmd2 = new SqlCommand("SELECT ResourceTypeId, ResourceId FROM dbo.Resource WHERE IsHistory = 0 AND IsDeleted = 0 AND ResourceTypeId = @ResourceTypeId OPTION (LOOP JOIN)", conn); // no need to sort to simulate random access cmd2.Parameters.AddWithValue("@ResourceTypeId", resourceTypeId); cmd2.CommandTimeout = 0; using var reader = cmd2.ExecuteReader(); @@ -606,10 +682,10 @@ private static BlobContainerClient GetContainer(string storageConnectionString, } } - private static IEnumerable GetLinesInBlobs(BlobContainerClient container) + private static IEnumerable GetLinesInBlobs(BlobContainerClient container, string nameFilter) { var linesRead = 0; - var blobs = container.GetBlobs().Where(_ => _.Name.Contains(_nameFilter, StringComparison.OrdinalIgnoreCase)).Skip(_skipBlobs).Take(_takeBlobs); + var blobs = container.GetBlobs().Where(_ => _.Name.Contains(nameFilter, StringComparison.OrdinalIgnoreCase)).Skip(_skipBlobs).Take(_takeBlobs); foreach (var blob in blobs) { if (linesRead >= _calls) @@ -938,6 +1014,140 @@ private static string GetResource(string resourceType, string resourceId) return status; } + private static void GetObservationsForPatient(string patientId) + { + var sw = Stopwatch.StartNew(); + var status = string.Empty; + var uri = new Uri(_endpoint + "/Observation?patient=" + patientId); + var count = 0; + try + { + var response = _httpClient.GetAsync(uri).Result; + status = response.StatusCode.ToString(); + var content = response.Content.ReadAsStringAsync().Result; + var split = content.Split("fullUrl", StringSplitOptions.None); + count = split.Length - 1; + } + catch (Exception e) + { + Console.WriteLine($"uri={uri} error={e.Message}"); + _store.TryLogEvent("Diag.GetObservationsForPatient", "Error", $"id={patientId} error={e.Message}", null, CancellationToken.None).Wait(); + } + + _store.TryLogEvent("Diag.GetObservationsForPatient", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec status={status} count={count} id={patientId}", null, CancellationToken.None).Wait(); + } + + private static void GetPatientRevIncludeObservations(string patientId) + { + var sw = Stopwatch.StartNew(); + var status = string.Empty; + var uri = new Uri(_endpoint + "/Patient?_revinclude=Observation:patient&_id=" + patientId); + var count = 0; + try + { + var response = _httpClient.GetAsync(uri).Result; + status = response.StatusCode.ToString(); + var content = response.Content.ReadAsStringAsync().Result; + var split = content.Split("fullUrl", StringSplitOptions.None); + count = split.Length - 1; + } + catch (Exception e) + { + Console.WriteLine($"uri={uri} error={e.Message}"); + _store.TryLogEvent("Diag.GetPatientRevIncludeObservations", "Error", $"id={patientId} error={e.Message}", null, CancellationToken.None).Wait(); + } + + _store.TryLogEvent("Diag.GetPatientRevIncludeObservations", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec status={status} count={count} id={patientId}", null, CancellationToken.None).Wait(); + } + + private static void UpdateSearchParam(string resourceId) + { + var sw = Stopwatch.StartNew(); + try + { + using var conn = new SqlConnection(_connectionString); + conn.Open(); + using var cmd = new SqlCommand( + @" + DECLARE @Resources dbo.ResourceList + INSERT INTO @Resources + ( ResourceTypeId, ResourceId, RawResource, ResourceSurrogateId, Version, HasVersionToCompare, IsDeleted, IsHistory, KeepHistory, IsRawResourceMetaSet, SearchParamHash) + SELECT ResourceTypeId, ResourceId, RawResource, ResourceSurrogateId, Version, 1, 0, 0, 1, 1, 'Test' + FROM Resource + WHERE ResourceTypeId = 96 AND ResourceId = @ResourceId + EXECUTE UpdateResourceSearchParams @Resources = @Resources + ", + conn); + cmd.Parameters.AddWithValue("@ResourceId", resourceId); + cmd.ExecuteNonQuery(); + } + catch (Exception e) + { + Console.WriteLine($"Diag.UpdateSearchParams.Observation: Id={resourceId} error={e.Message}"); + _store.TryLogEvent($"Diag.UpdateSearchParams.Observation", "Error", $"id={resourceId} error={e.Message}", null, CancellationToken.None).Wait(); + } + + _store.TryLogEvent($"Diag.UpdateSearchParams.Observation", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec id={resourceId}", null, CancellationToken.None).Wait(); + + // check + try + { + using var conn = new SqlConnection(_connectionString); + conn.Open(); + using var cmd = new SqlCommand("SELECT SearchParamHash FROM Resource WHERE ResourceTypeId = 96 AND IsHistory = 0 AND ResourceId = @ResourceId", conn); + cmd.Parameters.AddWithValue("@ResourceId", resourceId); + var hash = (string)cmd.ExecuteScalar(); + if (hash != "Test") + { + throw new ArgumentException("Incorrect hash"); + } + } + catch (Exception e) + { + Console.WriteLine($"Diag.Check.UpdateSearchParams.Observation: Id={resourceId} error={e.Message}"); + _store.TryLogEvent($"Diag.Check.UpdateSearchParams.Observation", "Error", $"id={resourceId} error={e.Message}", null, CancellationToken.None).Wait(); + } + } + + private static void DeleteResource(string resourceType, string resourceId, bool isHard) + { + var sw = Stopwatch.StartNew(); + var status = string.Empty; + var uri = new Uri(_endpoint + "/" + resourceType + "/" + resourceId + (isHard ? "?hardDelete=true" : string.Empty)); + try + { + var response = _httpClient.DeleteAsync(uri).Result; + status = response.StatusCode.ToString(); + } + catch (Exception e) + { + Console.WriteLine($"uri={uri} error={e.Message}"); + _store.TryLogEvent($"Diag.{(isHard ? "Hard" : "Soft")}Delete.Observation", "Error", $"id={resourceId} error={e.Message}", null, CancellationToken.None).Wait(); + } + + _store.TryLogEvent($"Diag.{(isHard ? "Hard" : "Soft")}Delete.Observation", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec status={status} id={resourceId}", null, CancellationToken.None).Wait(); + + // check + sw = Stopwatch.StartNew(); + uri = new Uri(_endpoint + "/" + resourceType + "/" + resourceId + "/_history"); + var count = 0; + try + { + var response = _httpClient.GetAsync(uri).Result; + status = response.StatusCode.ToString(); + var content = response.Content.ReadAsStringAsync().Result; + var split = content.Split("fullUrl", StringSplitOptions.None); + count = split.Length - 1; + } + catch (Exception e) + { + Console.WriteLine($"uri={uri} error={e.Message}"); + _store.TryLogEvent($"Diag.Check{(isHard ? "Hard" : "Soft")}Delete.Observation", "Error", $"id={resourceId} error={e.Message}", null, CancellationToken.None).Wait(); + } + + _store.TryLogEvent($"Diag.Check{(isHard ? "Hard" : "Soft")}Delete.Observation", "Warn", $"{(int)sw.Elapsed.TotalMilliseconds} msec count={count} status={status} id={resourceId}", null, CancellationToken.None).Wait(); + } + private static bool IsNetworkError(Exception e) { return e.Message.Contains("connection attempt failed", StringComparison.OrdinalIgnoreCase) From 55b4bba3d746c99f7d1727decd18c5826c49d6ec Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 3 Jan 2025 08:04:51 -0800 Subject: [PATCH 091/111] Added checks of Tbls --- .../Features/Schema/Migrations/85.diff.sql | 8 +++++++- 1 file changed, 7 insertions(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 55fb264bb7..b51536f207 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -2325,6 +2325,12 @@ BEGIN TRY EXECUTE dbo.LogEvent @Process=@Process,@Status='End' + IF 0 < (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ResourceTbl') AND index_id IN (0,1)) + RAISERROR('ResourceTbl is not empty', 18, 127) + + IF 0 < (SELECT sum(row_count) FROM sys.dm_db_partition_stats WHERE object_Id = object_id('ReferenceSearchParamTbl') AND index_id IN (0,1)) + RAISERROR('ReferenceSearchParamTbl is not empty', 18, 127) + EXECUTE(' ALTER VIEW dbo.ReferenceSearchParam AS @@ -3891,5 +3897,5 @@ GO GO --DROP TABLE IF EXISTS ReferenceSearchParamTbl -- TODO: Remove table after deployment GO ---DROP PROCEDURE IF EXISTS tmp_MoveResources -- TODO: Remove table after deployment +DROP PROCEDURE IF EXISTS tmp_MoveResources GO From 9a0107946218b1eb7811d92f1e1255c846220ac4 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 3 Jan 2025 13:07:12 -0800 Subject: [PATCH 092/111] sending zero raw resource for reindex --- tools/PerfTester/Program.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/tools/PerfTester/Program.cs b/tools/PerfTester/Program.cs index 13f4a8608d..bad6bbc513 100644 --- a/tools/PerfTester/Program.cs +++ b/tools/PerfTester/Program.cs @@ -1072,7 +1072,7 @@ private static void UpdateSearchParam(string resourceId) DECLARE @Resources dbo.ResourceList INSERT INTO @Resources ( ResourceTypeId, ResourceId, RawResource, ResourceSurrogateId, Version, HasVersionToCompare, IsDeleted, IsHistory, KeepHistory, IsRawResourceMetaSet, SearchParamHash) - SELECT ResourceTypeId, ResourceId, RawResource, ResourceSurrogateId, Version, 1, 0, 0, 1, 1, 'Test' + SELECT ResourceTypeId, ResourceId, 0x0, ResourceSurrogateId, Version, 1, 0, 0, 1, 1, 'Test' FROM Resource WHERE ResourceTypeId = 96 AND ResourceId = @ResourceId EXECUTE UpdateResourceSearchParams @Resources = @Resources From 6983e72623dcdaa95f5830bf5c577dbb89a1e407 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 3 Jan 2025 15:57:34 -0800 Subject: [PATCH 093/111] Configurable sleep --- tools/PerfTester/App.config | 1 + tools/PerfTester/Program.cs | 3 ++- 2 files changed, 3 insertions(+), 1 deletion(-) diff --git a/tools/PerfTester/App.config b/tools/PerfTester/App.config index 8248d993cf..8e6b6a00fd 100644 --- a/tools/PerfTester/App.config +++ b/tools/PerfTester/App.config @@ -27,6 +27,7 @@ HttpGet, HttpCreate, HttpUpdate, HardDelete, GetObservationsByPatient, GetPatientRevIncludeObservations. First for are for observations. Threads, Calls, and Repeat parameters are ignored. --> + diff --git a/tools/PerfTester/Program.cs b/tools/PerfTester/Program.cs index bad6bbc513..88b968c57e 100644 --- a/tools/PerfTester/Program.cs +++ b/tools/PerfTester/Program.cs @@ -51,6 +51,7 @@ public static class Program private static readonly string _nameFilter = ConfigurationManager.AppSettings["NameFilter"]; private static readonly bool _writesEnabled = bool.Parse(ConfigurationManager.AppSettings["WritesEnabled"]); private static readonly int _repeat = int.Parse(ConfigurationManager.AppSettings["Repeat"]); + private static readonly int _diagSleepSec = int.Parse(ConfigurationManager.AppSettings["DiagSleepSec"]); private static SqlRetryService _sqlRetryService; private static SqlStoreClient _store; @@ -176,7 +177,7 @@ private static void Diag() } } - Thread.Sleep(5000); + Thread.Sleep(_diagSleepSec * 1000); loop++; } From 5dfcfac9c804b58cd8833960a34ca1c6ad30d825 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 5 Jan 2025 10:12:18 -0800 Subject: [PATCH 094/111] constraint name correction --- .../Features/Schema/Migrations/85.diff.sql | 2 +- .../Features/Schema/Migrations/85.sql | 2 +- .../Features/Schema/Sql/Tables/0_Resource.sql | 2 +- 3 files changed, 3 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index b51536f207..2326426038 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -94,7 +94,7 @@ BEGIN ,ResourceSurrogateId bigint NOT NULL ,ResourceIdInt bigint NOT NULL ,Version int NOT NULL - ,IsHistory bit NOT NULL CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) + ,IsHistory bit NOT NULL CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0, CONSTRAINT CH_CurrentResources_IsHistory CHECK (IsHistory = 0) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index 28bc58d9aa..afcbf27e67 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -361,7 +361,7 @@ CREATE TABLE dbo.CurrentResources ( HistoryTransactionId BIGINT NULL, FileId BIGINT NULL, OffsetInFile INT NULL CONSTRAINT PKC_CurrentResources_ResourceTypeId_ResourceSurrogateId PRIMARY KEY CLUSTERED (ResourceTypeId, ResourceSurrogateId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId), - CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0), + CONSTRAINT CH_CurrentResources_IsHistory CHECK (IsHistory = 0), CONSTRAINT U_CurrentResources_ResourceIdInt_ResourceTypeId UNIQUE (ResourceIdInt, ResourceTypeId) WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) ); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql index fa898eb339..01c48206fa 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Tables/0_Resource.sql @@ -72,7 +72,7 @@ CREATE TABLE dbo.CurrentResources ,ResourceSurrogateId bigint NOT NULL ,ResourceIdInt bigint NOT NULL ,Version int NOT NULL - ,IsHistory bit NOT NULL CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0, CONSTRAINT CH_ResourceCurrent_IsHistory CHECK (IsHistory = 0) + ,IsHistory bit NOT NULL CONSTRAINT DF_CurrentResources_IsHistory DEFAULT 0, CONSTRAINT CH_CurrentResources_IsHistory CHECK (IsHistory = 0) ,IsDeleted bit NOT NULL ,RequestMethod varchar(10) NULL ,IsRawResourceMetaSet bit NOT NULL CONSTRAINT DF_CurrentResources_IsRawResourceMetaSet DEFAULT 0 From 88cbc06e04f11c088ed823db7d72efe717d42118 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 5 Jan 2025 17:03:00 -0800 Subject: [PATCH 095/111] rebatched --- .../Features/Schema/Migrations/85.diff.sql | 597 +++++++++--------- 1 file changed, 312 insertions(+), 285 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql index 2326426038..d4cfaf9bf8 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.diff.sql @@ -59,12 +59,8 @@ CREATE TYPE dbo.ResourceListLake AS TABLE ,UNIQUE (ResourceTypeId, ResourceId, Version) ) GO -IF EXISTS (SELECT * FROM sys.objects WHERE name = 'Resource' AND type = 'u') +IF object_id('ResourceIdIntMap') IS NULL BEGIN - BEGIN TRANSACTION - - EXECUTE sp_rename 'Resource', 'ResourceTbl' - CREATE TABLE dbo.ResourceIdIntMap ( ResourceTypeId smallint NOT NULL @@ -76,7 +72,10 @@ BEGIN ) ALTER TABLE dbo.ResourceIdIntMap SET ( LOCK_ESCALATION = AUTO ) - +END +GO +IF object_id('RawResources') IS NULL +BEGIN CREATE TABLE dbo.RawResources ( ResourceTypeId smallint NOT NULL @@ -87,7 +86,10 @@ BEGIN ) ALTER TABLE dbo.RawResources SET ( LOCK_ESCALATION = AUTO ) - +END +GO +IF object_id('CurrentResources') IS NULL +BEGIN CREATE TABLE dbo.CurrentResources ( ResourceTypeId smallint NOT NULL @@ -114,7 +116,10 @@ BEGIN CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.CurrentResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.CurrentResources (HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - +END +GO +IF object_id('HistoryResources') IS NULL +BEGIN CREATE TABLE dbo.HistoryResources ( ResourceTypeId smallint NOT NULL @@ -141,8 +146,65 @@ BEGIN CREATE INDEX IX_TransactionId_ResourceTypeId_WHERE_TransactionId_NOT_NULL ON dbo.HistoryResources (TransactionId, ResourceTypeId) WHERE TransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) CREATE INDEX IX_HistoryTransactionId_ResourceTypeId_WHERE_HistoryTransactionId_NOT_NULL ON dbo.HistoryResources (HistoryTransactionId, ResourceTypeId) WHERE HistoryTransactionId IS NOT NULL WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) - - EXECUTE(' +END +GO +IF object_id('ResourceReferenceSearchParams') IS NULL +BEGIN + CREATE TABLE dbo.ResourceReferenceSearchParams + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceTypeId smallint NOT NULL + ,ReferenceResourceIdInt bigint NOT NULL + ,IsResourceRef bit NOT NULL CONSTRAINT DF_ResourceReferenceSearchParams_IsResourceRef DEFAULT 1, CONSTRAINT CH_ResourceReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 1) + ) + + ALTER TABLE dbo.ResourceReferenceSearchParams ADD CONSTRAINT FK_ResourceReferenceSearchParams_ReferenceResourceIdInt_ReferenceResourceTypeId_ResourceIdIntMap FOREIGN KEY (ReferenceResourceIdInt, ReferenceResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + + ALTER TABLE dbo.ResourceReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) + + CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.ResourceReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.ResourceReferenceSearchParams (ReferenceResourceIdInt, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +END +GO +IF object_id('StringReferenceSearchParams') IS NULL +BEGIN + CREATE TABLE dbo.StringReferenceSearchParams + ( + ResourceTypeId smallint NOT NULL + ,ResourceSurrogateId bigint NOT NULL + ,SearchParamId smallint NOT NULL + ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL + ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL + ,IsResourceRef bit NOT NULL CONSTRAINT DF_StringReferenceSearchParams_IsResourceRef DEFAULT 0, CONSTRAINT CH_StringReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 0) + ) + + ALTER TABLE dbo.StringReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) + + CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId + ON dbo.StringReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + + CREATE UNIQUE INDEX IXU_ReferenceResourceId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId + ON dbo.StringReferenceSearchParams (ReferenceResourceId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) + WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +END +GO +IF EXISTS (SELECT * FROM sys.objects WHERE name = 'Resource' AND type = 'u') +BEGIN + BEGIN TRY + BEGIN TRANSACTION + + EXECUTE sp_rename 'Resource', 'ResourceTbl' + + EXECUTE('-- Resource CREATE VIEW dbo.Resource AS SELECT A.ResourceTypeId @@ -201,168 +263,8 @@ SELECT ResourceTypeId FROM dbo.ResourceTbl ') - EXECUTE(' -ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY -AS -set nocount on -DECLARE @st datetime = getUTCdate() - ,@SP varchar(100) = ''GetResources'' - ,@InputRows int - ,@DummyTop bigint = 9223372036854775807 - ,@NotNullVersionExists bit - ,@NullVersionExists bit - ,@MinRT smallint - ,@MaxRT smallint - -SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys - -DECLARE @Mode varchar(100) = ''RT=[''+convert(varchar,@MinRT)+'',''+convert(varchar,@MaxRT)+''] Cnt=''+convert(varchar,@InputRows)+'' NNVE=''+convert(varchar,@NotNullVersionExists)+'' NVE=''+convert(varchar,@NullVersionExists) - -BEGIN TRY - IF @NotNullVersionExists = 1 - IF @NullVersionExists = 0 - SELECT * - FROM (SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version - UNION ALL - SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,B.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,NULL - ,NULL - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version - ) A - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - ELSE - SELECT * - FROM (SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version - UNION ALL - SELECT B.ResourceTypeId - ,B.ResourceId - ,C.ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 - LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId - UNION ALL - SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,B.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,NULL - ,NULL - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A - JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version - UNION ALL - SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,B.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,NULL - ,NULL - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A - JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - WHERE IsHistory = 0 - ) A - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - ELSE - SELECT * - FROM (SELECT B.ResourceTypeId - ,B.ResourceId - ,C.ResourceSurrogateId - ,C.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,FileId - ,OffsetInFile - FROM (SELECT * FROM @ResourceKeys) A - INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt - LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId - UNION ALL - SELECT B.ResourceTypeId - ,B.ResourceId - ,ResourceSurrogateId - ,B.Version - ,IsDeleted - ,IsHistory - ,RawResource - ,IsRawResourceMetaSet - ,SearchParamHash - ,NULL - ,NULL - FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A - JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId - WHERE IsHistory = 0 - ) A - OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount -END TRY -BEGIN CATCH - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st; - THROW -END CATCH - ') - - COMMIT TRANSACTION -END -GO -CREATE OR ALTER VIEW dbo.CurrentResource + EXECUTE('-- CurrentResource +ALTER VIEW dbo.CurrentResource AS SELECT A.ResourceTypeId ,A.ResourceSurrogateId @@ -400,8 +302,10 @@ SELECT ResourceTypeId ,NULL FROM dbo.ResourceTbl WHERE IsHistory = 0 -GO -CREATE OR ALTER TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT + ') + + EXECUTE('-- ResourceIns +CREATE TRIGGER dbo.ResourceIns ON dbo.Resource INSTEAD OF INSERT AS BEGIN INSERT INTO dbo.RawResources @@ -425,7 +329,9 @@ BEGIN WHERE IsHistory = 1 AND NOT EXISTS (SELECT * FROM dbo.HistoryResources B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) END -GO + ') + + EXECUTE('-- ResourceUpd CREATE OR ALTER TRIGGER dbo.ResourceUpd ON dbo.Resource INSTEAD OF UPDATE AS BEGIN @@ -519,7 +425,7 @@ BEGIN END IF NOT UPDATE(IsHistory) - RAISERROR('Generic updates are not supported via Resource view',18,127) + RAISERROR(''Generic updates are not supported via Resource view'',18,127) UPDATE A SET IsHistory = 1 @@ -537,8 +443,10 @@ BEGIN WHERE IsHistory = 1 AND ResourceIdInt IS NOT NULL END -GO -CREATE OR ALTER TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE + ') + + EXECUTE('-- ResourceDel +CREATE TRIGGER dbo.ResourceDel ON dbo.Resource INSTEAD OF DELETE AS BEGIN DELETE FROM A @@ -550,64 +458,176 @@ BEGIN WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 0) DELETE FROM A - FROM dbo.HistoryResources A - WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) - - DELETE FROM A - FROM dbo.RawResources A - WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) -END -GO -IF EXISTS (SELECT * FROM sys.objects WHERE name = 'ReferenceSearchParam' AND type = 'u') -BEGIN - BEGIN TRANSACTION - - EXECUTE sp_rename 'ReferenceSearchParam', 'ReferenceSearchParamTbl' - - CREATE TABLE dbo.ResourceReferenceSearchParams - ( - ResourceTypeId smallint NOT NULL - ,ResourceSurrogateId bigint NOT NULL - ,SearchParamId smallint NOT NULL - ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL - ,ReferenceResourceTypeId smallint NOT NULL - ,ReferenceResourceIdInt bigint NOT NULL - ,IsResourceRef bit NOT NULL CONSTRAINT DF_ResourceReferenceSearchParams_IsResourceRef DEFAULT 1, CONSTRAINT CH_ResourceReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 1) - ) - - ALTER TABLE dbo.ResourceReferenceSearchParams ADD CONSTRAINT FK_ResourceReferenceSearchParams_ReferenceResourceIdInt_ReferenceResourceTypeId_ResourceIdIntMap FOREIGN KEY (ReferenceResourceIdInt, ReferenceResourceTypeId) REFERENCES dbo.ResourceIdIntMap (ResourceIdInt, ResourceTypeId) + FROM dbo.HistoryResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId AND B.IsHistory = 1) - ALTER TABLE dbo.ResourceReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) + DELETE FROM A + FROM dbo.RawResources A + WHERE EXISTS (SELECT * FROM Deleted B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceSurrogateId = A.ResourceSurrogateId) +END + ') - CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId - ON dbo.ResourceReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) - WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + EXECUTE('-- GetResources +ALTER PROCEDURE dbo.GetResources @ResourceKeys dbo.ResourceKeyList READONLY +AS +set nocount on +DECLARE @st datetime = getUTCdate() + ,@SP varchar(100) = ''GetResources'' + ,@InputRows int + ,@DummyTop bigint = 9223372036854775807 + ,@NotNullVersionExists bit + ,@NullVersionExists bit + ,@MinRT smallint + ,@MaxRT smallint - CREATE UNIQUE INDEX IXU_ReferenceResourceIdInt_ReferenceResourceTypeId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId - ON dbo.ResourceReferenceSearchParams (ReferenceResourceIdInt, ReferenceResourceTypeId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) - WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) +SELECT @MinRT = min(ResourceTypeId), @MaxRT = max(ResourceTypeId), @InputRows = count(*), @NotNullVersionExists = max(CASE WHEN Version IS NOT NULL THEN 1 ELSE 0 END), @NullVersionExists = max(CASE WHEN Version IS NULL THEN 1 ELSE 0 END) FROM @ResourceKeys - CREATE TABLE dbo.StringReferenceSearchParams - ( - ResourceTypeId smallint NOT NULL - ,ResourceSurrogateId bigint NOT NULL - ,SearchParamId smallint NOT NULL - ,BaseUri varchar(128) COLLATE Latin1_General_100_CS_AS NULL - ,ReferenceResourceId varchar(768) COLLATE Latin1_General_100_CS_AS NOT NULL - ,IsResourceRef bit NOT NULL CONSTRAINT DF_StringReferenceSearchParams_IsResourceRef DEFAULT 0, CONSTRAINT CH_StringReferenceSearchParams_IsResourceRef CHECK (IsResourceRef = 0) - ) +DECLARE @Mode varchar(100) = ''RT=[''+convert(varchar,@MinRT)+'',''+convert(varchar,@MaxRT)+''] Cnt=''+convert(varchar,@InputRows)+'' NNVE=''+convert(varchar,@NotNullVersionExists)+'' NVE=''+convert(varchar,@NullVersionExists) - ALTER TABLE dbo.StringReferenceSearchParams SET ( LOCK_ESCALATION = AUTO ) +BEGIN TRY + IF @NotNullVersionExists = 1 + IF @NullVersionExists = 0 + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,NULL + ,NULL + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + ) A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NOT NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.Resource C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,C.ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys WHERE Version IS NULL) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt AND C.IsHistory = 0 + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,NULL + ,NULL + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NOT NULL) A + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId_Version) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.Version = A.Version + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,NULL + ,NULL + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys WHERE Version IS NULL) A + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0 + ) A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) + ELSE + SELECT * + FROM (SELECT B.ResourceTypeId + ,B.ResourceId + ,C.ResourceSurrogateId + ,C.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,FileId + ,OffsetInFile + FROM (SELECT * FROM @ResourceKeys) A + INNER LOOP JOIN dbo.ResourceIdIntMap B WITH (INDEX = U_ResourceIdIntMap_ResourceId_ResourceTypeId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + INNER LOOP JOIN dbo.CurrentResources C ON C.ResourceTypeId = A.ResourceTypeId AND C.ResourceIdInt = B.ResourceIdInt + LEFT OUTER JOIN dbo.RawResources D ON D.ResourceTypeId = A.ResourceTypeId AND D.ResourceSurrogateId = C.ResourceSurrogateId + UNION ALL + SELECT B.ResourceTypeId + ,B.ResourceId + ,ResourceSurrogateId + ,B.Version + ,IsDeleted + ,IsHistory + ,RawResource + ,IsRawResourceMetaSet + ,SearchParamHash + ,NULL + ,NULL + FROM (SELECT TOP (@DummyTop) * FROM @ResourceKeys) A + JOIN dbo.ResourceTbl B WITH (INDEX = IX_Resource_ResourceTypeId_ResourceId) ON B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId + WHERE IsHistory = 0 + ) A + OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - CREATE CLUSTERED INDEX IXC_ResourceSurrogateId_SearchParamId_ResourceTypeId - ON dbo.StringReferenceSearchParams (ResourceSurrogateId, SearchParamId, ResourceTypeId) - WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount +END TRY +BEGIN CATCH + IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st; + THROW +END CATCH + ') - CREATE UNIQUE INDEX IXU_ReferenceResourceId_SearchParamId_BaseUri_ResourceSurrogateId_ResourceTypeId - ON dbo.StringReferenceSearchParams (ReferenceResourceId, SearchParamId, BaseUri, ResourceSurrogateId, ResourceTypeId) - WITH (DATA_COMPRESSION = PAGE) ON PartitionScheme_ResourceTypeId (ResourceTypeId) + EXECUTE sp_rename 'ReferenceSearchParam', 'ReferenceSearchParamTbl' - EXECUTE(' + EXECUTE('-- ReferenceSearchParam CREATE VIEW dbo.ReferenceSearchParam AS SELECT A.ResourceTypeId @@ -642,7 +662,7 @@ SELECT ResourceTypeId FROM dbo.ReferenceSearchParamTbl ') - EXECUTE(' + EXECUTE('-- ReferenceSearchParamDel CREATE TRIGGER dbo.ReferenceSearchParamDel ON dbo.ReferenceSearchParam INSTEAD OF DELETE AS BEGIN @@ -656,18 +676,12 @@ BEGIN END ') - COMMIT TRANSACTION -END -GO -BEGIN TRY - BEGIN TRANSACTION -- update ReferenceSearchParamList - DROP PROCEDURE CaptureResourceIdsForChanges DROP PROCEDURE MergeResources DROP PROCEDURE UpdateResourceSearchParams DROP TYPE ReferenceSearchParamList - EXECUTE(' + EXECUTE('-- ReferenceSearchParamList CREATE TYPE dbo.ReferenceSearchParamList AS TABLE ( ResourceTypeId smallint NOT NULL @@ -680,8 +694,9 @@ CREATE TYPE dbo.ReferenceSearchParamList AS TABLE UNIQUE (ResourceTypeId, ResourceSurrogateId, SearchParamId, BaseUri, ReferenceResourceTypeId, ReferenceResourceId) ) -') - EXECUTE(' + ') + + EXECUTE('-- CaptureResourceIdsForChanges CREATE PROCEDURE dbo.CaptureResourceIdsForChanges @Resources dbo.ResourceList READONLY, @ResourcesLake dbo.ResourceListLake READONLY AS set nocount on @@ -692,8 +707,9 @@ INSERT INTO dbo.ResourceChangeData FROM (SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @Resources UNION ALL SELECT ResourceId, ResourceTypeId, Version, IsHistory, IsDeleted FROM @ResourcesLake) A WHERE IsHistory = 0 ') - -- The following 2 procs and trigger are special for data movement - EXECUTE(' + + -- Special versions of procedures for data movement + EXECUTE('-- UpdateResourceSearchParams CREATE PROCEDURE dbo.UpdateResourceSearchParams @FailedResources int = 0 OUT ,@Resources dbo.ResourceList READONLY -- TODO: Remove after deployment @@ -964,7 +980,7 @@ BEGIN CATCH END CATCH ') - EXECUTE(' + EXECUTE('-- MergeResources CREATE PROCEDURE dbo.MergeResources -- This stored procedure can be used for: -- 1. Ordinary put with single version per resource in input @@ -1593,27 +1609,19 @@ BEGIN CATCH ELSE THROW END CATCH -') + ') - COMMIT TRANSACTION -END TRY -BEGIN CATCH - IF @@trancount > 0 ROLLBACK TRANSACTION - THROW -END CATCH -GO --- Special versions of procedures for data movement -GO + EXECUTE('-- GetResourcesByTypeAndSurrogateIdRange ALTER PROCEDURE dbo.GetResourcesByTypeAndSurrogateIdRange @ResourceTypeId smallint, @StartId bigint, @EndId bigint, @GlobalEndId bigint = NULL, @IncludeHistory bit = 1, @IncludeDeleted bit = 1 AS set nocount on -DECLARE @SP varchar(100) = 'GetResourcesByTypeAndSurrogateIdRange' - ,@Mode varchar(100) = 'RT='+isnull(convert(varchar,@ResourceTypeId),'NULL') - +' S='+isnull(convert(varchar,@StartId),'NULL') - +' E='+isnull(convert(varchar,@EndId),'NULL') - +' GE='+isnull(convert(varchar,@GlobalEndId),'NULL') - +' HI='+isnull(convert(varchar,@IncludeHistory),'NULL') - +' DE='+isnull(convert(varchar,@IncludeDeleted),'NULL') +DECLARE @SP varchar(100) = ''GetResourcesByTypeAndSurrogateIdRange'' + ,@Mode varchar(100) = ''RT=''+isnull(convert(varchar,@ResourceTypeId),''NULL'') + +'' S=''+isnull(convert(varchar,@StartId),''NULL'') + +'' E=''+isnull(convert(varchar,@EndId),''NULL'') + +'' GE=''+isnull(convert(varchar,@GlobalEndId),''NULL'') + +'' HI=''+isnull(convert(varchar,@IncludeHistory),''NULL'') + +'' DE=''+isnull(convert(varchar,@IncludeDeleted),''NULL'') ,@st datetime = getUTCdate() ,@DummyTop bigint = 9223372036854775807 ,@Rows int @@ -1675,19 +1683,21 @@ BEGIN TRY AND (IsDeleted = 0 OR @IncludeDeleted = 1) OPTION (MAXDOP 1, LOOP JOIN) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error''; THROW END CATCH -GO + ') + + EXECUTE('-- MergeResourcesDeleteInvisibleHistory ALTER PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory @TransactionId bigint, @AffectedRows int = NULL OUT AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId) + ,@Mode varchar(100) = ''T=''+convert(varchar,@TransactionId) ,@st datetime ,@Rows int ,@DeletedIdMap int @@ -1720,7 +1730,7 @@ BEGIN TRY FROM dbo.Resource A WHERE HistoryTransactionId = @TransactionId -- requires statistics to reflect not null values SET @Rows = @@rowcount - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='Resource',@Action='Delete',@Start=@st,@Rows=@Rows + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Run'',@Target=''Resource'',@Action=''Delete'',@Start=@st,@Rows=@Rows SET @AffectedRows += @Rows SET @st = getUTCdate() @@ -1741,20 +1751,20 @@ BEGIN TRY SET @DeletedIdMap = @@rowcount END END - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Start=@st,@Rows=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Run'',@Target=''ResourceIdIntMap'',@Action=''Delete'',@Start=@st,@Rows=@DeletedIdMap END COMMIT TRANSACTION SET @st = getUTCdate() UPDATE dbo.Resource SET TransactionId = NULL WHERE TransactionId = @TransactionId - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Target='Resource',@Action='Update',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Target=''Resource'',@Action=''Update'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error' - IF error_number() = 547 AND error_message() LIKE '%DELETE%' -- reference violation on DELETE + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'' + IF error_number() = 547 AND error_message() LIKE ''%DELETE%'' -- reference violation on DELETE BEGIN DELETE FROM @Ids GOTO Retry @@ -1762,12 +1772,14 @@ BEGIN CATCH ELSE THROW END CATCH -GO + ') + + EXECUTE('-- GetResourcesByTransactionId ALTER PROCEDURE dbo.GetResourcesByTransactionId @TransactionId bigint, @IncludeHistory bit = 0, @ReturnResourceKeysOnly bit = 0 AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(100) = 'T='+convert(varchar,@TransactionId)+' H='+convert(varchar,@IncludeHistory) + ,@Mode varchar(100) = ''T=''+convert(varchar,@TransactionId)+'' H=''+convert(varchar,@IncludeHistory) ,@st datetime = getUTCdate() BEGIN TRY @@ -1797,21 +1809,23 @@ BEGIN TRY WHERE TransactionId = @TransactionId AND (IsHistory = 0 OR @IncludeHistory = 1) OPTION (MAXDOP 1) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error''; THROW END CATCH -GO + ') + + EXECUTE('-- GetResourceVersions ALTER PROCEDURE dbo.GetResourceVersions @ResourceDateKeys dbo.ResourceDateKeyList READONLY AS -- This stored procedure allows to identifiy if version gap is available and checks dups on lastUpdated set nocount on DECLARE @st datetime = getUTCdate() - ,@SP varchar(100) = 'GetResourceVersions' - ,@Mode varchar(100) = 'Rows='+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) + ,@SP varchar(100) = ''GetResourceVersions'' + ,@Mode varchar(100) = ''Rows=''+convert(varchar,(SELECT count(*) FROM @ResourceDateKeys)) ,@DummyTop bigint = 9223372036854775807 BEGIN TRY @@ -1839,14 +1853,16 @@ BEGIN TRY OUTER APPLY (SELECT TOP 1 * FROM dbo.Resource B WHERE B.ResourceTypeId = A.ResourceTypeId AND B.ResourceId = A.ResourceId AND B.ResourceSurrogateId BETWEEN A.ResourceSurrogateId AND A.ResourceSurrogateId + 79999) D -- date OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1)) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Rows=@@rowcount END TRY BEGIN CATCH IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st; + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st; THROW END CATCH -GO + ') + + EXECUTE('-- HardDeleteResource ALTER PROCEDURE dbo.HardDeleteResource @ResourceTypeId smallint ,@ResourceId varchar(64) @@ -1856,7 +1872,7 @@ ALTER PROCEDURE dbo.HardDeleteResource AS set nocount on DECLARE @SP varchar(100) = object_name(@@procid) - ,@Mode varchar(200) = 'RT='+convert(varchar,@ResourceTypeId)+' R='+@ResourceId+' V='+convert(varchar,@KeepCurrentVersion) + ,@Mode varchar(200) = ''RT=''+convert(varchar,@ResourceTypeId)+'' R=''+@ResourceId+'' V=''+convert(varchar,@KeepCurrentVersion) ,@st datetime = getUTCdate() ,@TransactionId bigint ,@DeletedIdMap int = 0 @@ -1865,12 +1881,12 @@ DECLARE @SP varchar(100) = object_name(@@procid) IF @IsResourceChangeCaptureEnabled = 1 SET @MakeResourceInvisible = 1 -SET @Mode += ' I='+convert(varchar,@MakeResourceInvisible) +SET @Mode += '' I=''+convert(varchar,@MakeResourceInvisible) IF @MakeResourceInvisible = 1 BEGIN EXECUTE dbo.MergeResourcesBeginTransaction @Count = 1, @TransactionId = @TransactionId OUT - SET @Mode += ' T='+convert(varchar,@TransactionId) + SET @Mode += '' T=''+convert(varchar,@TransactionId) END DECLARE @Ids TABLE (ResourceSurrogateId bigint NOT NULL, ResourceIdInt bigint NULL) @@ -1969,13 +1985,13 @@ BEGIN TRY IF @MakeResourceInvisible = 1 EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Text=@DeletedIdMap + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''End'',@Start=@st,@Text=@DeletedIdMap END TRY BEGIN CATCH IF @@trancount > 0 ROLLBACK TRANSACTION - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st + EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status=''Error'',@Start=@st - IF error_number() = 547 AND error_message() LIKE '%DELETE%'-- reference violation on DELETE + IF error_number() = 547 AND error_message() LIKE ''%DELETE%''-- reference violation on DELETE BEGIN DELETE FROM @Ids DELETE FROM @RefIdsRaw @@ -1985,6 +2001,15 @@ BEGIN CATCH ELSE THROW END CATCH + ') + + COMMIT TRANSACTION + END TRY + BEGIN CATCH + IF @@trancount > 0 ROLLBACK TRANSACTION + THROW + END CATCH +END GO CREATE OR ALTER PROCEDURE dbo.tmp_MoveResources @ResourceTypeId smallint, @SurrogateId bigint, @CurrentMaxSurrogateId bigint, @LastProcessed varchar(100) AS @@ -2110,7 +2135,8 @@ BEGIN TRY EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='StringReferenceSearchParams',@Action='Insert',@Rows=@@rowcount,@Start=@st SET @st = getUTCdate() - DELETE FROM dbo.ReferenceSearchParamTbl + DELETE FROM A + FROM dbo.ReferenceSearchParamTbl A WITH (PAGLOCK) WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ReferenceSearchParamTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st @@ -2172,7 +2198,8 @@ BEGIN TRY BEGIN TRANSACTION SET @st = getUTCdate() - DELETE FROM dbo.ResourceTbl + DELETE FROM A + FROM dbo.ResourceTbl A WITH (PAGLOCK) WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId > @SurrogateId AND ResourceSurrogateId <= @CurrentMaxSurrogateId EXECUTE dbo.LogEvent @Process=@Process,@Status='Run',@Mode=@LastProcessed,@Target='ResourceTbl',@Action='Delete',@Rows=@@rowcount,@Start=@st From daa1ad9755d302667a7e9aac8440eb67d52e39ea Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 6 Jan 2025 14:33:42 -0800 Subject: [PATCH 096/111] removed commit with failure call --- .../Storage/SqlServerFhirDataStore.cs | 80 +++++++++++++------ 1 file changed, 57 insertions(+), 23 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index 3308a445c8..c108fe3937 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -131,44 +131,76 @@ public SqlServerFhirDataStore( internal static TimeSpan MergeResourcesTransactionHeartbeatPeriod => TimeSpan.FromSeconds(10); - private async Task PutRawResourcesIntoAdls(IReadOnlyList resources, long transactionId, CancellationToken cancellationToken) + private async Task DeleteBlobFromAdls(long transactionId, CancellationToken cancellationToken) { var start = DateTime.UtcNow; var sw = Stopwatch.StartNew(); - var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); var blobName = GetBlobNameForRaw(transactionId); - retry: - try + while (true) { - using var stream = await SqlAdlsCient.Container.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); - using var writer = new StreamWriter(stream); - var offset = 0; - foreach (var resource in resources) + try { - resource.FileId = transactionId; - resource.OffsetInFile = offset; - var line = resource.ResourceWrapper.RawResource.Data; - offset += Encoding.UTF8.GetByteCount(line) + eol; - await writer.WriteLineAsync(line); + await SqlAdlsCient.Container.GetBlockBlobClient(blobName).DeleteIfExistsAsync(cancellationToken: cancellationToken); + break; } + catch (Exception e) + { + await StoreClient.TryLogEvent("DeleteBlobFromAdls", "Error", $"blob={blobName} error={e.ToString()}", start, cancellationToken); + if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) + { + await Task.Delay(1000, cancellationToken); + continue; + } - #pragma warning disable CA2016 - await writer.FlushAsync(); + throw; + } } - catch (Exception e) + + var mcsec = (long)Math.Round(sw.Elapsed.TotalMilliseconds * 1000, 0); + await StoreClient.TryLogEvent("DeleteBlobFromAdls", "Warn", $"mcsec={mcsec} blob={blobName}", start, cancellationToken); + } + + private async Task PutRawResourcesIntoAdls(IReadOnlyList resources, long transactionId, CancellationToken cancellationToken) + { + var start = DateTime.UtcNow; + var sw = Stopwatch.StartNew(); + var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); + var blobName = GetBlobNameForRaw(transactionId); + while (true) { - await StoreClient.TryLogEvent("PutRawResourcesIntoAdls", "Error", e.ToString(), start, cancellationToken); - if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) + try { - await Task.Delay(1000, cancellationToken); - goto retry; + using var stream = await SqlAdlsCient.Container.GetBlockBlobClient(blobName).OpenWriteAsync(true, null, cancellationToken); + using var writer = new StreamWriter(stream); + var offset = 0; + foreach (var resource in resources) + { + resource.FileId = transactionId; + resource.OffsetInFile = offset; + var line = resource.ResourceWrapper.RawResource.Data; + offset += Encoding.UTF8.GetByteCount(line) + eol; + await writer.WriteLineAsync(line); + } + + #pragma warning disable CA2016 + await writer.FlushAsync(); + break; } + catch (Exception e) + { + await StoreClient.TryLogEvent("PutRawResourcesIntoAdls", "Error", $"blob={blobName} error={e.ToString()}", start, cancellationToken); + if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) + { + await Task.Delay(1000, cancellationToken); + continue; + } - throw; + throw; + } } var mcsec = (long)Math.Round(sw.Elapsed.TotalMilliseconds * 1000, 0); - await StoreClient.TryLogEvent("PutRawResourcesToAdls", "Warn", $"mcsec={mcsec} Resources={resources.Count}", start, cancellationToken); + await StoreClient.TryLogEvent("PutRawResourcesToAdls", "Warn", $"mcsec={mcsec} resources={resources.Count} blob={blobName}", start, cancellationToken); } internal static string GetBlobNameForRaw(long fileId) @@ -443,7 +475,9 @@ private async Task Date: Wed, 8 Jan 2025 17:34:09 -0800 Subject: [PATCH 097/111] Removed redundant tostring --- .../Features/Storage/SqlServerFhirDataStore.cs | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index c108fe3937..51809125f6 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -145,7 +145,7 @@ private async Task DeleteBlobFromAdls(long transactionId, CancellationToken canc } catch (Exception e) { - await StoreClient.TryLogEvent("DeleteBlobFromAdls", "Error", $"blob={blobName} error={e.ToString()}", start, cancellationToken); + await StoreClient.TryLogEvent("DeleteBlobFromAdls", "Error", $"blob={blobName} error={e}", start, cancellationToken); if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) { await Task.Delay(1000, cancellationToken); @@ -188,7 +188,7 @@ private async Task PutRawResourcesIntoAdls(IReadOnlyList r } catch (Exception e) { - await StoreClient.TryLogEvent("PutRawResourcesIntoAdls", "Error", $"blob={blobName} error={e.ToString()}", start, cancellationToken); + await StoreClient.TryLogEvent("PutRawResourcesIntoAdls", "Error", $"blob={blobName} error={e}", start, cancellationToken); if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) { await Task.Delay(1000, cancellationToken); From a16381de0071196655bfae78a3b3ab71ba225240 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Wed, 8 Jan 2025 22:23:47 -0800 Subject: [PATCH 098/111] ensure not null --- .../Features/Search/SqlServerSearchService.cs | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs index c49706af9f..1326202a81 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/SqlServerSearchService.cs @@ -552,7 +552,7 @@ await _sqlRetryService.ExecuteSql( // add raw resource to search entry var resources = new List(sqlSearchOptions.MaxItemCount); - var rawResources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); + var rawResources = SqlStoreClient.GetRawResourcesFromAdls(tmpResources.Where(_ => _.SqlBytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.FileId).Value, EnsureArg.IsNotNull(_.OffsetInFile).Value)).ToList()); foreach (var tmpResource in tmpResources) { if (!clonedSearchOptions.OnlyIds) @@ -560,7 +560,7 @@ await _sqlRetryService.ExecuteSql( var rawResource = new Lazy(() => { var decompressed = tmpResource.SqlBytes.IsNull - ? rawResources[(tmpResource.FileId.Value, tmpResource.OffsetInFile.Value)] + ? rawResources[(EnsureArg.IsNotNull(tmpResource.FileId).Value, EnsureArg.IsNotNull(tmpResource.OffsetInFile).Value)] : SqlStoreClient.ReadCompressedRawResource(tmpResource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource); _logger.LogVerbose(_parameterStore, cancellationToken, "{NameOfResourceSurrogateId}: {ResourceSurrogateId}; {NameOfResourceTypeId}: {ResourceTypeId}; Decompressed length: {RawResourceLength}", nameof(tmpResource.Entry.Resource.ResourceSurrogateId), tmpResource.Entry.Resource.ResourceSurrogateId, nameof(tmpResource.Entry.Resource.ResourceTypeName), tmpResource.Entry.Resource.ResourceTypeName, decompressed.Length); if (string.IsNullOrEmpty(decompressed)) @@ -704,11 +704,11 @@ await _sqlRetryService.ExecuteSql( _logger, null, cancellationToken); - var rawResources = SqlStoreClient.GetRawResourcesFromAdls(resources.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); + var rawResources = SqlStoreClient.GetRawResourcesFromAdls(resources.Where(_ => _.SqlBytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.FileId).Value, EnsureArg.IsNotNull(_.OffsetInFile).Value)).ToList()); foreach (var resource in resources) { var rawResource = resource.SqlBytes.IsNull - ? rawResources[(resource.FileId.Value, resource.OffsetInFile.Value)] + ? rawResources[(EnsureArg.IsNotNull(resource.FileId).Value, EnsureArg.IsNotNull(resource.OffsetInFile).Value)] : SqlStoreClient.ReadCompressedRawResource(resource.SqlBytes, _compressedRawResourceConverter.ReadCompressedRawResource); if (string.IsNullOrEmpty(rawResource)) From 806f877452e35ebf267bb84dc7c5b34f17cc6f6d Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 9 Jan 2025 06:56:14 -0800 Subject: [PATCH 099/111] more ensure --- .../Features/Storage/SqlStoreClient.cs | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 926d34cac0..38d28a3a29 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -97,7 +97,7 @@ public async Task> GetAsync(IReadOnlyList> ReadResourceWrappers(SqlCommand cmd, Func decompress, Func getResourceTypeName, bool isReadOnly, bool readRequestMethod, CancellationToken cancellationToken, bool includeInvisible = false) { var wrappers = (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadTemporaryResourceWrapper(reader, readRequestMethod, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).ToList(); - var rawResources = GetRawResourcesFromAdls(wrappers.Where(_ => _.SqlBytes.IsNull).Select(_ => (_.FileId.Value, _.OffsetInFile.Value)).ToList()); + var rawResources = GetRawResourcesFromAdls(wrappers.Where(_ => _.SqlBytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.FileId).Value, EnsureArg.IsNotNull(_.OffsetInFile).Value)).ToList()); foreach (var wrapper in wrappers) { wrapper.Wrapper.RawResource = new RawResource(wrapper.SqlBytes.IsNull ? rawResources[(wrapper.FileId.Value, wrapper.OffsetInFile.Value)] : ReadCompressedRawResource(wrapper.SqlBytes, decompress), FhirResourceFormat.Json, wrapper.IsMetaSet); @@ -190,7 +190,7 @@ internal static string ReadCompressedRawResource(SqlBytes bytes, Func _.Item2.matchedVersion != null && _.Item2.matchedBytes.IsNull).Select(_ => (_.Item2.matchedFileId.Value, _.Item2.matchedOffsetInFile.Value)).ToList(); + var refs = tmpResources.Where(_ => _.Item2.matchedVersion != null && _.Item2.matchedBytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.Item2.matchedFileId).Value, EnsureArg.IsNotNull(_.Item2.matchedOffsetInFile).Value)).ToList(); var rawResources = GetRawResourcesFromAdls(refs); var resources = tmpResources.Select(_ => { @@ -198,7 +198,7 @@ internal static string ReadCompressedRawResource(SqlBytes bytes, Func Date: Thu, 9 Jan 2025 11:47:00 -0800 Subject: [PATCH 100/111] more ensure --- .../Features/Storage/SqlStoreClient.cs | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 38d28a3a29..5cb6933998 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -100,7 +100,7 @@ private async Task> ReadResourceWrappers(SqlComma var rawResources = GetRawResourcesFromAdls(wrappers.Where(_ => _.SqlBytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.FileId).Value, EnsureArg.IsNotNull(_.OffsetInFile).Value)).ToList()); foreach (var wrapper in wrappers) { - wrapper.Wrapper.RawResource = new RawResource(wrapper.SqlBytes.IsNull ? rawResources[(wrapper.FileId.Value, wrapper.OffsetInFile.Value)] : ReadCompressedRawResource(wrapper.SqlBytes, decompress), FhirResourceFormat.Json, wrapper.IsMetaSet); + wrapper.Wrapper.RawResource = new RawResource(wrapper.SqlBytes.IsNull ? rawResources[(EnsureArg.IsNotNull(wrapper.FileId).Value, EnsureArg.IsNotNull(wrapper.OffsetInFile).Value)] : ReadCompressedRawResource(wrapper.SqlBytes, decompress), FhirResourceFormat.Json, wrapper.IsMetaSet); } return wrappers.Where(_ => includeInvisible || _.Wrapper.RawResource.Data != InvisibleResource).Select(_ => _.Wrapper).ToList(); From 49bbdbd21d68e908c24d249c1c6d3f717511d09f Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Thu, 9 Jan 2025 16:46:21 -0800 Subject: [PATCH 101/111] import tests with raw in lake --- .../Rest/Import/ImportTests.cs | 6 +++++- 1 file changed, 5 insertions(+), 1 deletion(-) diff --git a/test/Microsoft.Health.Fhir.Shared.Tests.E2E/Rest/Import/ImportTests.cs b/test/Microsoft.Health.Fhir.Shared.Tests.E2E/Rest/Import/ImportTests.cs index 63546f7646..ecaa9bcfbb 100644 --- a/test/Microsoft.Health.Fhir.Shared.Tests.E2E/Rest/Import/ImportTests.cs +++ b/test/Microsoft.Health.Fhir.Shared.Tests.E2E/Rest/Import/ImportTests.cs @@ -53,6 +53,10 @@ public ImportTests(ImportTestFixture fixture) _client = fixture.TestFhirClient; _metricHandler = fixture.MetricHandler; _fixture = fixture; + if (_fixture.IsUsingInProcTestServer) + { + ExecuteSql("INSERT INTO Parameters (Id,Char) SELECT 'MergeResources.AdlsConnectionString','UseDevelopmentStorage=true'"); + } } [Fact] @@ -138,7 +142,7 @@ CREATE TRIGGER Transactions_Trigger ON Transactions FOR UPDATE var message = await ImportWaitAsync(registration.CheckLocation, false); Assert.Equal(requestedExceptions == 6 ? HttpStatusCode.InternalServerError : HttpStatusCode.OK, message.StatusCode); var retries = (int)ExecuteSql("SELECT count(*) FROM EventLog WHERE Process = 'MergeResourcesCommitTransaction' AND Status = 'Error'"); - Assert.Equal(requestedExceptions == 6 ? 5 : 3, retries); + Assert.Equal(requestedExceptions == 6 ? 4 : 3, retries); } finally { From 5f44cc76537a9c7bc54532d8f4f72416ddcb142b Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sat, 11 Jan 2025 16:25:45 -0800 Subject: [PATCH 102/111] minus data lake --- tools/Exporter/Exporter.csproj | 1 - 1 file changed, 1 deletion(-) diff --git a/tools/Exporter/Exporter.csproj b/tools/Exporter/Exporter.csproj index daf9b05fc1..1e26b8ddda 100644 --- a/tools/Exporter/Exporter.csproj +++ b/tools/Exporter/Exporter.csproj @@ -13,7 +13,6 @@ - From 99a8c7abae0ba592a61d2119fc694847d53f99ba Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sat, 11 Jan 2025 16:30:13 -0800 Subject: [PATCH 103/111] minus data lake --- Directory.Packages.props | 3 +-- 1 file changed, 1 insertion(+), 2 deletions(-) diff --git a/Directory.Packages.props b/Directory.Packages.props index 584100c9cc..f4e78d27e8 100644 --- a/Directory.Packages.props +++ b/Directory.Packages.props @@ -6,7 +6,6 @@ - @@ -126,4 +125,4 @@ - \ No newline at end of file + From 609ff9e017d78c158cb261702e8151f68d705244 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 12 Jan 2025 21:17:38 -0800 Subject: [PATCH 104/111] Removed not used stored proc --- .../Sql/Sprocs/CleanupResourceIdIntMap.sql | 109 ------------------ 1 file changed, 109 deletions(-) delete mode 100644 src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql deleted file mode 100644 index 862d87d51e..0000000000 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/CleanupResourceIdIntMap.sql +++ /dev/null @@ -1,109 +0,0 @@ ---DROP PROCEDURE dbo.CleanupResourceIdIntMap -GO -CREATE PROCEDURE dbo.CleanupResourceIdIntMap @ResetAfter bit = 0 -AS -set nocount on -DECLARE @SP varchar(100) = 'CleanupResourceIdIntMap' - ,@Mode varchar(100) = 'R='+isnull(convert(varchar,@ResetAfter),'NULL') - ,@st datetime = getUTCdate() - ,@Id varchar(100) = 'CleanupResourceIdIntMap.LastProcessed.TypeId.ResourceIdInt' - ,@ResourceTypeId smallint - ,@ResourceIdInt bigint - ,@RowsToProcess int - ,@ProcessedRows int = 0 - ,@DeletedRows int = 0 - ,@ReportDate datetime = getUTCdate() -DECLARE @LastProcessed varchar(100) = isnull((SELECT Char FROM dbo.Parameters WHERE Id = @Id),'0.0') - -BEGIN TRY - INSERT INTO dbo.Parameters (Id, Char) SELECT @SP, 'LogEvent' - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Start' - - INSERT INTO dbo.Parameters (Id, Char) SELECT @Id, '0.0' - - DECLARE @Types TABLE (ResourceTypeId smallint PRIMARY KEY, Name varchar(100)) - DECLARE @ResourceIdInts TABLE (ResourceIdInt bigint PRIMARY KEY) - - INSERT INTO @Types EXECUTE dbo.GetUsedResourceTypes - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@Types',@Action='Insert',@Rows=@@rowcount - - SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 1) - SET @ResourceIdInt = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255) -- (SELECT value FROM string_split(@LastProcessed, '.', 1) WHERE ordinal = 2) - - DELETE FROM @Types WHERE ResourceTypeId < @ResourceTypeId - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@Types',@Action='Delete',@Rows=@@rowcount - - WHILE EXISTS (SELECT * FROM @Types) -- Processing in ASC order - BEGIN - SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId FROM @Types ORDER BY ResourceTypeId) - - SET @ProcessedRows = 0 - SET @DeletedRows = 0 - SET @RowsToProcess = 1 - WHILE @RowsToProcess > 0 - BEGIN - DELETE FROM @ResourceIdInts - - INSERT INTO @ResourceIdInts - SELECT TOP 100000 - ResourceIdInt - FROM dbo.ResourceIdIntMap - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceIdInt > @ResourceIdInt - ORDER BY - ResourceIdInt - SET @RowsToProcess = @@rowcount - SET @ProcessedRows += @RowsToProcess - - IF @RowsToProcess > 0 - SET @ResourceIdInt = (SELECT max(ResourceIdInt) FROM @ResourceIdInts) - - SET @LastProcessed = convert(varchar,@ResourceTypeId)+'.'+convert(varchar,@ResourceIdInt) - - DELETE FROM A FROM @ResourceIdInts A WHERE EXISTS (SELECT * FROM dbo.CurrentResources B WHERE B.ResourceTypeId = @ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@ResourceIdInts.Current',@Action='Delete',@Rows=@@rowcount,@Text=@LastProcessed - - DELETE FROM A FROM @ResourceIdInts A WHERE EXISTS (SELECT * FROM dbo.HistoryResources B WHERE B.ResourceTypeId = @ResourceTypeId AND B.ResourceIdInt = A.ResourceIdInt) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@ResourceIdInts.History',@Action='Delete',@Rows=@@rowcount,@Text=@LastProcessed - - DELETE FROM A FROM @ResourceIdInts A WHERE EXISTS (SELECT * FROM dbo.ResourceReferenceSearchParams B WHERE B.ReferenceResourceTypeId = @ResourceTypeId AND B.ReferenceResourceIdInt = A.ResourceIdInt) - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='@ResourceIdInts.Reference',@Action='Delete',@Rows=@@rowcount,@Text=@LastProcessed - - IF EXISTS (SELECT * FROM @ResourceIdInts) - BEGIN - DELETE FROM A FROM dbo.ResourceIdIntMap A WHERE A.ResourceTypeId = @ResourceTypeId AND EXISTS (SELECT * FROM @ResourceIdInts B WHERE B.ResourceIdInt = A.ResourceIdInt) - SET @DeletedRows += @@rowcount - END - - UPDATE dbo.Parameters SET Char = @LastProcessed WHERE Id = @Id - - IF datediff(second, @ReportDate, getUTCdate()) > 60 - BEGIN - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Select',@Rows=@ProcessedRows,@Text=@LastProcessed - SET @ReportDate = getUTCdate() - SET @ProcessedRows = 0 - END - END - - DELETE FROM @Types WHERE ResourceTypeId = @ResourceTypeId - - SET @ResourceIdInt = 0 - END - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Run',@Target='ResourceIdIntMap',@Action='Delete',@Rows=@DeletedRows,@Text=@LastProcessed - - IF @ResetAfter = 1 DELETE FROM dbo.Parameters WHERE Id = @Id - - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st -END TRY -BEGIN CATCH - IF error_number() = 1750 THROW -- Real error is before 1750, cannot trap in SQL. - EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error'; - THROW -END CATCH -GO ---EXECUTE dbo.CleanupResourceIdIntMap 1 ---SELECT * FROM Parameters WHERE Id = 'CleanupResourceIdIntMap.LastProcessed.TypeId.ResourceIdInt' ---SELECT TOP 100 * FROM EventLog WHERE EventDate > dateadd(minute,-10,getUTCdate()) AND Process = 'CleanupResourceIdIntMap' ORDER BY EventDate DESC ---INSERT INTO Parameters (Id, Char) SELECT 'CleanupResourceIdIntMap','LogEvent' From 983a5da899adeea158f9a1f2f71b99930f4ad415 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Sun, 12 Jan 2025 21:30:14 -0800 Subject: [PATCH 105/111] reverted formatting change --- .../QueryGenerators/SqlQueryGenerator.cs | 16 ++++++++-------- 1 file changed, 8 insertions(+), 8 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs index 811b1986f8..f9080ec8e7 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Search/Expressions/Visitors/QueryGenerators/SqlQueryGenerator.cs @@ -274,15 +274,15 @@ public override object VisitSqlRoot(SqlRootExpression expression, SearchOptions if (IsPrimaryKeySort(searchOptions)) { StringBuilder.AppendDelimited(", ", searchOptions.Sort, (sb, sort) => + { + Column column = sort.searchParameterInfo.Name switch { - Column column = sort.searchParameterInfo.Name switch - { - SearchParameterNames.ResourceType => VLatest.Resource.ResourceTypeId, - SearchParameterNames.LastUpdated => VLatest.Resource.ResourceSurrogateId, - _ => throw new InvalidOperationException($"Unexpected sort parameter {sort.searchParameterInfo.Name}"), - }; - sb.Append(column, resourceTableAlias).Append(" ").Append(sort.sortOrder == SortOrder.Ascending ? "ASC" : "DESC"); - }) + SearchParameterNames.ResourceType => VLatest.Resource.ResourceTypeId, + SearchParameterNames.LastUpdated => VLatest.Resource.ResourceSurrogateId, + _ => throw new InvalidOperationException($"Unexpected sort parameter {sort.searchParameterInfo.Name}"), + }; + sb.Append(column, resourceTableAlias).Append(" ").Append(sort.sortOrder == SortOrder.Ascending ? "ASC" : "DESC"); + }) .AppendLine(); } else if (IsSortValueNeeded(searchOptions)) From feb856224ddd744e0d5117e782d1ef8848ee27a4 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 13 Jan 2025 08:42:24 -0800 Subject: [PATCH 106/111] comments --- .../Features/Storage/SqlAdlsCient.cs | 5 +++-- .../Features/Storage/SqlServerFhirDataStore.cs | 18 ++++++++++-------- .../Features/Storage/SqlStoreClient.cs | 6 +++--- 3 files changed, 16 insertions(+), 13 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs index db57bfa1e0..af64330b34 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs @@ -87,9 +87,10 @@ private static string GetStorageParameter(ISqlRetryService sqlRetryService, ILog var value = cmd.ExecuteScalarAsync(sqlRetryService, logger, CancellationToken.None).Result; return value == null ? null : (string)value; } - catch (Exception) + catch (Exception e) { - return null; + logger.LogError(e, $"Failed to get storage parameter from Parameters.{parameterId}"); + throw; } } } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index 51809125f6..e28160ebd0 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -131,10 +131,11 @@ public SqlServerFhirDataStore( internal static TimeSpan MergeResourcesTransactionHeartbeatPeriod => TimeSpan.FromSeconds(10); - private async Task DeleteBlobFromAdls(long transactionId, CancellationToken cancellationToken) + private async Task DeleteBlobFromAdlsAsync(long transactionId, CancellationToken cancellationToken) { var start = DateTime.UtcNow; var sw = Stopwatch.StartNew(); + var retries = 0; var blobName = GetBlobNameForRaw(transactionId); while (true) { @@ -145,8 +146,8 @@ private async Task DeleteBlobFromAdls(long transactionId, CancellationToken canc } catch (Exception e) { - await StoreClient.TryLogEvent("DeleteBlobFromAdls", "Error", $"blob={blobName} error={e}", start, cancellationToken); - if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) + await StoreClient.TryLogEvent("DeleteBlobFromAdlsAsync", "Error", $"blob={blobName} error={e}", start, cancellationToken); + if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase) && retries++ < 3) { await Task.Delay(1000, cancellationToken); continue; @@ -157,14 +158,15 @@ private async Task DeleteBlobFromAdls(long transactionId, CancellationToken canc } var mcsec = (long)Math.Round(sw.Elapsed.TotalMilliseconds * 1000, 0); - await StoreClient.TryLogEvent("DeleteBlobFromAdls", "Warn", $"mcsec={mcsec} blob={blobName}", start, cancellationToken); + await StoreClient.TryLogEvent("DeleteBlobFromAdlsAsync", "Warn", $"mcsec={mcsec} blob={blobName}", start, cancellationToken); } - private async Task PutRawResourcesIntoAdls(IReadOnlyList resources, long transactionId, CancellationToken cancellationToken) + private async Task PutRawResourcesIntoAdlsAsync(IReadOnlyList resources, long transactionId, CancellationToken cancellationToken) { var start = DateTime.UtcNow; var sw = Stopwatch.StartNew(); var eol = Encoding.UTF8.GetByteCount(Environment.NewLine); + var retries = 0; var blobName = GetBlobNameForRaw(transactionId); while (true) { @@ -188,8 +190,8 @@ private async Task PutRawResourcesIntoAdls(IReadOnlyList r } catch (Exception e) { - await StoreClient.TryLogEvent("PutRawResourcesIntoAdls", "Error", $"blob={blobName} error={e}", start, cancellationToken); - if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase)) + await StoreClient.TryLogEvent("PutRawResourcesIntoAdlsAsync", "Error", $"blob={blobName} error={e}", start, cancellationToken); + if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase) && retries++ < 3) { await Task.Delay(1000, cancellationToken); continue; @@ -799,7 +801,7 @@ internal async Task MergeResourcesWrapperAsync(long transactionId, bool singleTr cmd.Parameters.AddWithValue("@SingleTransaction", singleTransaction); if (_schemaInformation.Current >= SchemaVersionConstants.Lake && SqlAdlsCient.Container != null) { - await PutRawResourcesIntoAdls(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource + await PutRawResourcesIntoAdlsAsync(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource } if (_schemaInformation.Current >= SchemaVersionConstants.Lake) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 5cb6933998..2db5e9f85b 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -77,7 +77,7 @@ public async Task> GetAsync(IReadOnlyList> GetAsync(IReadOnlyList> ReadResourceWrappers(SqlCommand cmd, Func decompress, Func getResourceTypeName, bool isReadOnly, bool readRequestMethod, CancellationToken cancellationToken, bool includeInvisible = false) + private async Task> ReadResourceWrappersAsync(SqlCommand cmd, Func decompress, Func getResourceTypeName, bool isReadOnly, bool readRequestMethod, CancellationToken cancellationToken, bool includeInvisible = false) { var wrappers = (await cmd.ExecuteReaderAsync(_sqlRetryService, (reader) => { return ReadTemporaryResourceWrapper(reader, readRequestMethod, getResourceTypeName); }, _logger, cancellationToken, isReadOnly: isReadOnly)).ToList(); var rawResources = GetRawResourcesFromAdls(wrappers.Where(_ => _.SqlBytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.FileId).Value, EnsureArg.IsNotNull(_.OffsetInFile).Value)).ToList()); @@ -210,7 +210,7 @@ internal async Task> GetResourcesByTransactionIdA { await using var cmd = new SqlCommand() { CommandText = "dbo.GetResourcesByTransactionId", CommandType = CommandType.StoredProcedure, CommandTimeout = 600 }; cmd.Parameters.AddWithValue("@TransactionId", transactionId); - return await ReadResourceWrappers(cmd, decompress, getResourceTypeName, false, true, cancellationToken, false); + return await ReadResourceWrappersAsync(cmd, decompress, getResourceTypeName, false, true, cancellationToken, false); } private static (ResourceWrapper Wrapper, bool IsMetaSet, SqlBytes SqlBytes, long? FileId, int? OffsetInFile) ReadTemporaryResourceWrapper(SqlDataReader reader, bool readRequestMethod, Func getResourceTypeName) From a309c924d4b63d4759751cc6578ee4dceda95585 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 13 Jan 2025 11:08:22 -0800 Subject: [PATCH 107/111] Removed item2 --- .../Features/Storage/SqlStoreClient.cs | 9 ++++++--- 1 file changed, 6 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index 2db5e9f85b..a9e5723286 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -186,17 +186,20 @@ internal static string ReadCompressedRawResource(SqlBytes bytes, Func 6 ? reader.Read(table.OffsetInFile, 7) : null; } - return (new ResourceDateKey(resourceTypeId, resourceId, resourceSurrogateId, version.ToString(CultureInfo.InvariantCulture)), (matchedVersion, matchedBytes, matchedFileId, matchedOffsetInFile)); + (ResourceDateKey DateKey, (string Version, SqlBytes Bytes, long? FileId, int? OffsetInFile) Matched) result; + result.DateKey = new ResourceDateKey(resourceTypeId, resourceId, resourceSurrogateId, version.ToString(CultureInfo.InvariantCulture)); + result.Matched = (matchedVersion, matchedBytes, matchedFileId, matchedOffsetInFile); + return result; }, _logger, cancellationToken); - var refs = tmpResources.Where(_ => _.Item2.matchedVersion != null && _.Item2.matchedBytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.Item2.matchedFileId).Value, EnsureArg.IsNotNull(_.Item2.matchedOffsetInFile).Value)).ToList(); + var refs = tmpResources.Where(_ => _.Matched.Version != null && _.Matched.Bytes.IsNull).Select(_ => (EnsureArg.IsNotNull(_.Matched.FileId).Value, EnsureArg.IsNotNull(_.Matched.OffsetInFile).Value)).ToList(); var rawResources = GetRawResourcesFromAdls(refs); var resources = tmpResources.Select(_ => { var (key, (version, bytes, fileId, offsetInFile)) = _; RawResource rawResource = null; - if (_.Item2.matchedVersion != null) + if (_.Matched.Version != null) { rawResource = new RawResource(bytes.IsNull ? rawResources[(EnsureArg.IsNotNull(fileId).Value, EnsureArg.IsNotNull(offsetInFile).Value)] : ReadCompressedRawResource(bytes, decompress), FhirResourceFormat.Json, false); } From f8501885ed303aaaebbd5b71bc00022742b387bf Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 13 Jan 2025 12:02:25 -0800 Subject: [PATCH 108/111] Cient -> Client --- .../Storage/{SqlAdlsCient.cs => SqlAdlsClient.cs} | 4 ++-- .../Features/Storage/SqlServerFhirDataStore.cs | 10 +++++----- .../Features/Storage/SqlStoreClient.cs | 4 ++-- 3 files changed, 9 insertions(+), 9 deletions(-) rename src/Microsoft.Health.Fhir.SqlServer/Features/Storage/{SqlAdlsCient.cs => SqlAdlsClient.cs} (98%) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsClient.cs similarity index 98% rename from src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs rename to src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsClient.cs index af64330b34..8104232026 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsCient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlAdlsClient.cs @@ -13,7 +13,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Storage { - internal class SqlAdlsCient + internal class SqlAdlsClient { private static readonly object _parameterLocker = new object(); private static string _adlsContainerName; @@ -25,7 +25,7 @@ internal class SqlAdlsCient private static BlobContainerClient _adlsContainer; private static bool _adlsIsSet; - public SqlAdlsCient(ISqlRetryService sqlRetryService, ILogger logger) + public SqlAdlsClient(ISqlRetryService sqlRetryService, ILogger logger) { EnsureArg.IsNotNull(sqlRetryService, nameof(sqlRetryService)); diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index e28160ebd0..0abe108f58 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -124,7 +124,7 @@ public SqlServerFhirDataStore( } } - _ = new SqlAdlsCient(_sqlRetryService, _logger); + _ = new SqlAdlsClient(_sqlRetryService, _logger); } internal SqlStoreClient StoreClient => _sqlStoreClient; @@ -141,7 +141,7 @@ private async Task DeleteBlobFromAdlsAsync(long transactionId, CancellationToken { try { - await SqlAdlsCient.Container.GetBlockBlobClient(blobName).DeleteIfExistsAsync(cancellationToken: cancellationToken); + await SqlAdlsClient.Container.GetBlockBlobClient(blobName).DeleteIfExistsAsync(cancellationToken: cancellationToken); break; } catch (Exception e) @@ -172,7 +172,7 @@ private async Task PutRawResourcesIntoAdlsAsync(IReadOnlyList= SchemaVersionConstants.Lake && SqlAdlsCient.Container != null) + if (_schemaInformation.Current >= SchemaVersionConstants.Lake && SqlAdlsClient.Container != null) { await PutRawResourcesIntoAdlsAsync(mergeWrappers, transactionId, cancellationToken); // this sets offset so resource row generator does not add raw resource } @@ -878,7 +878,7 @@ public async Task GetAsync(ResourceKey key, CancellationToken c public async Task HardDeleteAsync(ResourceKey key, bool keepCurrentVersion, bool allowPartialSuccess, CancellationToken cancellationToken) { - var makeResourceInvisible = _coreFeatures.SupportsResourceChangeCapture || SqlAdlsCient.Container != null; + var makeResourceInvisible = _coreFeatures.SupportsResourceChangeCapture || SqlAdlsClient.Container != null; await _sqlStoreClient.HardDeleteAsync(_model.GetResourceTypeId(key.ResourceType), key.Id, keepCurrentVersion, makeResourceInvisible, cancellationToken); } diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index a9e5723286..c379191420 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -114,7 +114,7 @@ private async Task> ReadResourceWrappersAsync(Sql return results; } - if (SqlAdlsCient.Container == null) + if (SqlAdlsClient.Container == null) { throw new InvalidOperationException("ADLS container is null."); } @@ -123,7 +123,7 @@ private async Task> ReadResourceWrappersAsync(Sql foreach (var file in resourceRefsByFile) { var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(file.Key); - var blobClient = SqlAdlsCient.Container.GetBlobClient(blobName); + var blobClient = SqlAdlsClient.Container.GetBlobClient(blobName); using var stream = blobClient.OpenRead(); using var reader = new StreamReader(stream); foreach (var offset in file) From 24430d0910c96a3b61fc4a12cae3fcdcd8156a25 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Mon, 13 Jan 2025 13:24:57 -0800 Subject: [PATCH 109/111] removed local var --- .../Features/Storage/SqlStoreClient.cs | 5 ++--- 1 file changed, 2 insertions(+), 3 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs index c379191420..6b0f464f57 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlStoreClient.cs @@ -197,14 +197,13 @@ internal static string ReadCompressedRawResource(SqlBytes bytes, Func { - var (key, (version, bytes, fileId, offsetInFile)) = _; RawResource rawResource = null; if (_.Matched.Version != null) { - rawResource = new RawResource(bytes.IsNull ? rawResources[(EnsureArg.IsNotNull(fileId).Value, EnsureArg.IsNotNull(offsetInFile).Value)] : ReadCompressedRawResource(bytes, decompress), FhirResourceFormat.Json, false); + rawResource = new RawResource(_.Matched.Bytes.IsNull ? rawResources[(EnsureArg.IsNotNull(_.Matched.FileId).Value, EnsureArg.IsNotNull(_.Matched.OffsetInFile).Value)] : ReadCompressedRawResource(_.Matched.Bytes, decompress), FhirResourceFormat.Json, false); } - return (key, (version, rawResource)); + return (_.DateKey, (_.Matched.Version, rawResource)); }).ToList(); return resources; } From 9e1d8a64768fb542ddb7b0d3ac22e363423d56c8 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Tue, 14 Jan 2025 15:40:45 -0800 Subject: [PATCH 110/111] revert disable indexes --- .../Features/Schema/Migrations/85.sql | 115 +----------------- .../Schema/Sql/Sprocs/DisableIndexes.sql | 2 +- 2 files changed, 2 insertions(+), 115 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql index afcbf27e67..8501ebc0bd 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/85.sql @@ -1651,119 +1651,6 @@ BEGIN CATCH THROW; END CATCH -GO -CREATE PROCEDURE dbo.CleanupResourceIdIntMap -@ResetAfter BIT=0 -AS -SET NOCOUNT ON; -DECLARE @SP AS VARCHAR (100) = 'CleanupResourceIdIntMap', @Mode AS VARCHAR (100) = 'R=' + isnull(CONVERT (VARCHAR, @ResetAfter), 'NULL'), @st AS DATETIME = getUTCdate(), @Id AS VARCHAR (100) = 'CleanupResourceIdIntMap.LastProcessed.TypeId.ResourceIdInt', @ResourceTypeId AS SMALLINT, @ResourceIdInt AS BIGINT, @RowsToProcess AS INT, @ProcessedRows AS INT = 0, @DeletedRows AS INT = 0, @ReportDate AS DATETIME = getUTCdate(); -DECLARE @LastProcessed AS VARCHAR (100) = isnull((SELECT Char - FROM dbo.Parameters - WHERE Id = @Id), '0.0'); -BEGIN TRY - INSERT INTO dbo.Parameters (Id, Char) - SELECT @SP, - 'LogEvent'; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Start'; - INSERT INTO dbo.Parameters (Id, Char) - SELECT @Id, - '0.0'; - DECLARE @Types TABLE ( - ResourceTypeId SMALLINT PRIMARY KEY, - Name VARCHAR (100)); - DECLARE @ResourceIdInts TABLE ( - ResourceIdInt BIGINT PRIMARY KEY); - INSERT INTO @Types - EXECUTE dbo.GetUsedResourceTypes ; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Insert', @Rows = @@rowcount; - SET @ResourceTypeId = substring(@LastProcessed, 1, charindex('.', @LastProcessed) - 1); - SET @ResourceIdInt = substring(@LastProcessed, charindex('.', @LastProcessed) + 1, 255); - DELETE @Types - WHERE ResourceTypeId < @ResourceTypeId; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@Types', @Action = 'Delete', @Rows = @@rowcount; - WHILE EXISTS (SELECT * - FROM @Types) - BEGIN - SET @ResourceTypeId = (SELECT TOP 1 ResourceTypeId - FROM @Types - ORDER BY ResourceTypeId); - SET @ProcessedRows = 0; - SET @DeletedRows = 0; - SET @RowsToProcess = 1; - WHILE @RowsToProcess > 0 - BEGIN - DELETE @ResourceIdInts; - INSERT INTO @ResourceIdInts - SELECT TOP 100000 ResourceIdInt - FROM dbo.ResourceIdIntMap - WHERE ResourceTypeId = @ResourceTypeId - AND ResourceIdInt > @ResourceIdInt - ORDER BY ResourceIdInt; - SET @RowsToProcess = @@rowcount; - SET @ProcessedRows += @RowsToProcess; - IF @RowsToProcess > 0 - SET @ResourceIdInt = (SELECT max(ResourceIdInt) - FROM @ResourceIdInts); - SET @LastProcessed = CONVERT (VARCHAR, @ResourceTypeId) + '.' + CONVERT (VARCHAR, @ResourceIdInt); - DELETE A - FROM @ResourceIdInts AS A - WHERE EXISTS (SELECT * - FROM dbo.CurrentResources AS B - WHERE B.ResourceTypeId = @ResourceTypeId - AND B.ResourceIdInt = A.ResourceIdInt); - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@ResourceIdInts.Current', @Action = 'Delete', @Rows = @@rowcount, @Text = @LastProcessed; - DELETE A - FROM @ResourceIdInts AS A - WHERE EXISTS (SELECT * - FROM dbo.HistoryResources AS B - WHERE B.ResourceTypeId = @ResourceTypeId - AND B.ResourceIdInt = A.ResourceIdInt); - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@ResourceIdInts.History', @Action = 'Delete', @Rows = @@rowcount, @Text = @LastProcessed; - DELETE A - FROM @ResourceIdInts AS A - WHERE EXISTS (SELECT * - FROM dbo.ResourceReferenceSearchParams AS B - WHERE B.ReferenceResourceTypeId = @ResourceTypeId - AND B.ReferenceResourceIdInt = A.ResourceIdInt); - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = '@ResourceIdInts.Reference', @Action = 'Delete', @Rows = @@rowcount, @Text = @LastProcessed; - IF EXISTS (SELECT * - FROM @ResourceIdInts) - BEGIN - DELETE A - FROM dbo.ResourceIdIntMap AS A - WHERE A.ResourceTypeId = @ResourceTypeId - AND EXISTS (SELECT * - FROM @ResourceIdInts AS B - WHERE B.ResourceIdInt = A.ResourceIdInt); - SET @DeletedRows += @@rowcount; - END - UPDATE dbo.Parameters - SET Char = @LastProcessed - WHERE Id = @Id; - IF datediff(second, @ReportDate, getUTCdate()) > 60 - BEGIN - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'ResourceIdIntMap', @Action = 'Select', @Rows = @ProcessedRows, @Text = @LastProcessed; - SET @ReportDate = getUTCdate(); - SET @ProcessedRows = 0; - END - END - DELETE @Types - WHERE ResourceTypeId = @ResourceTypeId; - SET @ResourceIdInt = 0; - END - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Run', @Target = 'ResourceIdIntMap', @Action = 'Delete', @Rows = @DeletedRows, @Text = @LastProcessed; - IF @ResetAfter = 1 - DELETE dbo.Parameters - WHERE Id = @Id; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'End', @Start = @st; -END TRY -BEGIN CATCH - IF error_number() = 1750 - THROW; - EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Error'; - THROW; -END CATCH - GO CREATE OR ALTER PROCEDURE dbo.ConfigurePartitionOnResourceChanges @numberOfFuturePartitionsToAdd INT @@ -2377,7 +2264,7 @@ BEGIN TRY AND IndexName = Ind); EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = 'IndexProperties', @Action = 'Insert', @Rows = @@rowcount; DELETE @Indexes - WHERE Tbl IN ('Resource', 'ResourceCurrent', 'ResourceHistory') + WHERE Tbl = 'Resource' OR IndId = 1; EXECUTE dbo.LogEvent @Process = @SP, @Mode = @Mode, @Status = 'Info', @Target = '@Indexes', @Action = 'Delete', @Rows = @@rowcount; WHILE EXISTS (SELECT * diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql index eae8002cf7..776ed1ac45 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/DisableIndexes.sql @@ -39,7 +39,7 @@ BEGIN TRY WHERE NOT EXISTS (SELECT * FROM dbo.IndexProperties WHERE TableName = Tbl AND IndexName = Ind) EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='IndexProperties',@Action='Insert',@Rows=@@rowcount - DELETE FROM @Indexes WHERE Tbl IN ('Resource','ResourceCurrent','ResourceHistory') OR IndId = 1 + DELETE FROM @Indexes WHERE Tbl = 'Resource' OR IndId = 1 EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Info',@Target='@Indexes',@Action='Delete',@Rows=@@rowcount WHILE EXISTS (SELECT * FROM @Indexes) From 02c47a5e7a46f143ce00b260baa16ecaa6cf2037 Mon Sep 17 00:00:00 2001 From: Sergey Galuzo Date: Fri, 17 Jan 2025 21:43:40 -0800 Subject: [PATCH 111/111] Single resource per blob --- .../Storage/SqlServerFhirDataStore.cs | 32 +++++++------------ .../Features/Storage/SqlStoreClient.cs | 20 ++++++------ 2 files changed, 21 insertions(+), 31 deletions(-) diff --git a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs index 0abe108f58..b9138bfc6f 100644 --- a/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs +++ b/src/Microsoft.Health.Fhir.SqlServer/Features/Storage/SqlServerFhirDataStore.cs @@ -131,12 +131,12 @@ public SqlServerFhirDataStore( internal static TimeSpan MergeResourcesTransactionHeartbeatPeriod => TimeSpan.FromSeconds(10); - private async Task DeleteBlobFromAdlsAsync(long transactionId, CancellationToken cancellationToken) + private async Task DeleteBlobFromAdlsAsync(long transactionId, int blobIndex, CancellationToken cancellationToken) { var start = DateTime.UtcNow; var sw = Stopwatch.StartNew(); var retries = 0; - var blobName = GetBlobNameForRaw(transactionId); + var blobName = GetBlobNameForRaw(transactionId, blobIndex); while (true) { try @@ -165,32 +165,24 @@ private async Task PutRawResourcesIntoAdlsAsync(IReadOnlyList { - resource.FileId = transactionId; - resource.OffsetInFile = offset; - var line = resource.ResourceWrapper.RawResource.Data; - offset += Encoding.UTF8.GetByteCount(line) + eol; - await writer.WriteLineAsync(line); - } + resources[index].FileId = transactionId; + resources[index].OffsetInFile = index; + var blobClient = SqlAdlsClient.Container.GetBlobClient(GetBlobNameForRaw(transactionId, index)); + blobClient.Upload(BinaryData.FromString(resources[index].ResourceWrapper.RawResource.Data + Environment.NewLine), overwrite: true); + }); - #pragma warning disable CA2016 - await writer.FlushAsync(); break; } catch (Exception e) { - await StoreClient.TryLogEvent("PutRawResourcesIntoAdlsAsync", "Error", $"blob={blobName} error={e}", start, cancellationToken); + await StoreClient.TryLogEvent("PutRawResourcesIntoAdlsAsync", "Error", $"transactionId={transactionId} error={e}", start, cancellationToken); if (e.ToString().Contains("ConditionNotMet", StringComparison.OrdinalIgnoreCase) && retries++ < 3) { await Task.Delay(1000, cancellationToken); @@ -202,12 +194,12 @@ private async Task PutRawResourcesIntoAdlsAsync(IReadOnlyList> ReadResourceWrappersAsync(Sql throw new InvalidOperationException("ADLS container is null."); } - var resourceRefsByFile = resourceRefs.GroupBy(_ => _.FileId); - foreach (var file in resourceRefsByFile) + Parallel.ForEach(resourceRefs, resourceRef => { - var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(file.Key); + var blobName = SqlServerFhirDataStore.GetBlobNameForRaw(resourceRef.FileId, resourceRef.OffsetInFile); var blobClient = SqlAdlsClient.Container.GetBlobClient(blobName); - using var stream = blobClient.OpenRead(); - using var reader = new StreamReader(stream); - foreach (var offset in file) + var result = blobClient.Download(); + using var streamReader = new StreamReader(result.Value.Content); + var rawResource = streamReader.ReadLine(); + lock (results) { - reader.DiscardBufferedData(); - stream.Position = offset.OffsetInFile; - var line = reader.ReadLine(); - results.Add((file.Key, offset.OffsetInFile), line); + results.Add((resourceRef.FileId, resourceRef.OffsetInFile), rawResource); } - } + }); return results; }