Skip to content

Commit

Permalink
Invisible history records (#3398)
Browse files Browse the repository at this point in the history
* Invisible history records

* next

* removed not used parameter

* HistoryTransactionId

* hard deletes

* watchdog test

* HardDeleteResource_2

* hard delete test
  • Loading branch information
SergeyGaluzo authored Jul 14, 2023
1 parent 5c44f4c commit b63ece6
Show file tree
Hide file tree
Showing 27 changed files with 7,627 additions and 194 deletions.

Large diffs are not rendered by default.

6,433 changes: 6,433 additions & 0 deletions src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/59.sql

Large diffs are not rendered by default.

Original file line number Diff line number Diff line change
Expand Up @@ -68,5 +68,6 @@ public enum SchemaVersion
V56 = 56,
V57 = 57,
V58 = 58,
V59 = 59,
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -7,9 +7,9 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema
{
public static class SchemaVersionConstants
{
public const int Min = (int)SchemaVersion.V58;
public const int Max = (int)SchemaVersion.V58;
public const int MinForUpgrade = (int)SchemaVersion.V53; // this is used for upgrade tests only
public const int Min = (int)SchemaVersion.V59;
public const int Max = (int)SchemaVersion.V59;
public const int MinForUpgrade = (int)SchemaVersion.V56; // 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;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,6 @@ Go

INSERT INTO dbo.SchemaVersion
VALUES
(58, 'started')
(59, 'started')

Go
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
--DROP PROCEDURE dbo.GetTransactions
GO
CREATE PROCEDURE dbo.GetTransactions @StartNotInclusiveTranId bigint, @EndInclusiveTranId bigint, @EndDate datetime = NULL
AS
set nocount on
DECLARE @SP varchar(100) = object_name(@@procid)
,@Mode varchar(100) = 'ST='+convert(varchar,@StartNotInclusiveTranId)+' ET='+convert(varchar,@EndInclusiveTranId)+' ED='+isnull(convert(varchar,@EndDate,121),'NULL')
,@st 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
--SELECT TOP 100 * FROM Transactions ORDER BY SurrogateIdRangeFirstValue DESC
--EXECUTE GetTransactions 5105975696064002770, 5105975696807769789
Original file line number Diff line number Diff line change
@@ -0,0 +1,71 @@
CREATE 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)

IF @IsResourceChangeCaptureEnabled = 0
DELETE dbo.Resource
OUTPUT deleted.ResourceSurrogateId INTO @SurrogateIds
WHERE ResourceTypeId = @ResourceTypeId
AND ResourceId = @ResourceId
AND (@KeepCurrentVersion = 0 OR IsHistory = 1)
AND RawResource <> 0xF
ELSE
BEGIN
UPDATE dbo.Resource
SET IsHistory = 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
END

IF @KeepCurrentVersion = 0
BEGIN
DELETE dbo.ResourceWriteClaim WHERE ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.CompartmentAssignment WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.ReferenceSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.TokenSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.TokenText WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.StringSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.UriSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.NumberSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.QuantitySearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.DateTimeSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.ReferenceTokenCompositeSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.TokenTokenCompositeSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.TokenDateTimeCompositeSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.TokenQuantityCompositeSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.TokenStringCompositeSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
DELETE dbo.TokenNumberNumberCompositeSearchParam WHERE ResourceTypeId = @ResourceTypeId AND ResourceSurrogateId IN (SELECT ResourceSurrogateId FROM @SurrogateIds)
END

IF @@trancount > 0 COMMIT TRANSACTION

IF @IsResourceChangeCaptureEnabled = 1 EXECUTE dbo.MergeResourcesCommitTransaction @TransactionId
END TRY
BEGIN CATCH
IF @@trancount > 0 ROLLBACK TRANSACTION
EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error',@Start=@st;
THROW
END CATCH
GO

This file was deleted.

Original file line number Diff line number Diff line change
Expand Up @@ -30,7 +30,7 @@ CREATE PROCEDURE dbo.MergeResources
AS
set nocount on
DECLARE @st datetime = getUTCdate()
,@SP varchar(100) = 'MergeResources'
,@SP varchar(100) = object_name(@@procid)
,@DummyTop bigint = 9223372036854775807
,@InitialTranCount int = @@trancount
,@IsRetry bit = 0
Expand Down Expand Up @@ -114,8 +114,16 @@ BEGIN TRY
SET IsHistory = 1
WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 1)
SET @AffectedRows += @@rowcount

DELETE FROM dbo.Resource WHERE EXISTS (SELECT * FROM @PreviousSurrogateIds WHERE TypeId = ResourceTypeId AND SurrogateId = ResourceSurrogateId AND KeepHistory = 0)

IF @IsResourceChangeCaptureEnabled = 1
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)
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
--DROP PROCEDURE dbo.MergeResourcesDeleteInvisibleHistory
GO
CREATE 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 = getUTCdate()
,@TypeId 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 FROM dbo.Resource WHERE ResourceTypeId = @TypeId AND HistoryTransactionId = @TransactionId AND IsHistory = 1 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
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
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
--DROP PROCEDURE dbo.MergeResourcesPutTransactionInvisibleHistory
GO
CREATE PROCEDURE dbo.MergeResourcesPutTransactionInvisibleHistory @TransactionId bigint
AS
set nocount on
DECLARE @SP varchar(100) = object_name(@@procid)
,@Mode varchar(100)= 'TR='+convert(varchar,@TransactionId)
,@st 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 -- Real error is before 1750, cannot trap in SQL.
EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='Error';
THROW
END CATCH
GO
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,8 @@
RawResource varbinary(max) NOT NULL,
IsRawResourceMetaSet bit NOT NULL DEFAULT 0,
SearchParamHash varchar(64) NULL,
TransactionId bigint 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)
Expand All @@ -19,6 +20,7 @@
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
(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -14,6 +14,7 @@
,HeartbeatDate datetime NOT NULL CONSTRAINT DF_Transactions_HeartbeatDate DEFAULT getUTCdate()
,FailureReason varchar(max) NULL -- is populated at the end of data load on failure
,IsControlledByClient bit NOT NULL CONSTRAINT DF_Transactions_IsControlledByClient DEFAULT 1
,InvisibleHistoryRemovedDate datetime NULL

CONSTRAINT PKC_Transactions_SurrogateIdRangeFirstValue PRIMARY KEY CLUSTERED (SurrogateIdRangeFirstValue)
)
Expand Down
Loading

0 comments on commit b63ece6

Please sign in to comment.