Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Refactor last updated deduping after UTC change #3890

Merged
merged 14 commits into from
Jun 3, 2024
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
--DROP PROCEDURE dbo.GetResourceVersions
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
-- 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
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
--DECLARE @ResourceDateKeys dbo.ResourceDateKeyList
--SELECT ResourceTypeId, ResourceId, ResourceSurrogateId, Version, IsHistory FROM Resource WHERE ResourceTypeId = 100 AND ResourceId = '00036927-6ef5-38cc-947d-b7900257b33e'
--DELETE FROM Resource WHERE ResourceTypeId = 100 AND ResourceSurrogateId = 5105560146179009828
--INSERT INTO @ResourceDateKeys SELECT TOP 1 ResourceTypeId, ResourceId, 5105560060153802438 FROM Resource WHERE ResourceTypeId = 100
--EXECUTE dbo.GetResourceVersions @ResourceDateKeys
5,141 changes: 5,141 additions & 0 deletions src/Microsoft.Health.Fhir.SqlServer/Features/Schema/Migrations/82.sql

Large diffs are not rendered by default.

Original file line number Diff line number Diff line change
Expand Up @@ -91,5 +91,6 @@ public enum SchemaVersion
V79 = 79,
V80 = 80,
V81 = 81,
V82 = 82,
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ namespace Microsoft.Health.Fhir.SqlServer.Features.Schema
public static class SchemaVersionConstants
{
public const int Min = (int)SchemaVersion.V75;
public const int Max = (int)SchemaVersion.V81;
public const int Max = (int)SchemaVersion.V82;
public const int MinForUpgrade = (int)SchemaVersion.V75; // this is used for upgrade tests only
public const int SearchParameterStatusSchemaVersion = (int)SchemaVersion.V6;
public const int SupportForReferencesWithMissingTypeVersion = (int)SchemaVersion.V7;
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,6 @@ Go

INSERT INTO dbo.SchemaVersion
VALUES
(81, 'started')
(82, 'started')

Go
Original file line number Diff line number Diff line change
Expand Up @@ -13,24 +13,21 @@ 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 conflict for the caller.
-- 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 EXISTS (SELECT *
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
)
THEN 0 -- input lastUpdated matches stored
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
-- ResourceIndex allows to deal with more than one late arrival per resource
,MatchedVersion = isnull(D.Version,0)
,MatchedRawResource = D.RawResource
-- 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
OPTION (MAXDOP 1, OPTIMIZE FOR (@DummyTop = 1))

EXECUTE dbo.LogEvent @Process=@SP,@Mode=@Mode,@Status='End',@Start=@st,@Rows=@@rowcount
Expand Down
Loading
Loading