-
Notifications
You must be signed in to change notification settings - Fork 518
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
* Invisible history records * next * removed not used parameter * HistoryTransactionId * hard deletes * watchdog test * HardDeleteResource_2 * hard delete test
- Loading branch information
1 parent
5c44f4c
commit b63ece6
Showing
27 changed files
with
7,627 additions
and
194 deletions.
There are no files selected for viewing
588 changes: 588 additions & 0 deletions
588
src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/59.diff.sql
Large diffs are not rendered by default.
Oops, something went wrong.
6,433 changes: 6,433 additions & 0 deletions
6,433
src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/59.sql
Large diffs are not rendered by default.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -68,5 +68,6 @@ public enum SchemaVersion | |
V56 = 56, | ||
V57 = 57, | ||
V58 = 58, | ||
V59 = 59, | ||
} | ||
} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -19,6 +19,6 @@ Go | |
|
||
INSERT INTO dbo.SchemaVersion | ||
VALUES | ||
(58, 'started') | ||
(59, 'started') | ||
|
||
Go |
25 changes: 25 additions & 0 deletions
25
src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/GetTransactions.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
71 changes: 71 additions & 0 deletions
71
src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
99 changes: 0 additions & 99 deletions
99
src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/HardDeleteResource_2.sql
This file was deleted.
Oops, something went wrong.
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
34 changes: 34 additions & 0 deletions
34
...Health.Fhir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesDeleteInvisibleHistory.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
23 changes: 23 additions & 0 deletions
23
...hir.SqlServer/Features/Schema/Sql/Sprocs/MergeResourcesPutTransactionInvisibleHistory.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.