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
|
CREATE SCHEMA velu;
GO
CREATE TABLE velu.Ancre
(
Id INT IDENTITY(1,1) CONSTRAINT PKAncre PRIMARY KEY,
); -- Table d'ancrage : pas d'historisation : C'est AncreCondition qui garde l'état des données
GO
CREATE TABLE velu.AncreLabel
(
Id INT NOT NULL CONSTRAINT pkAncreLabel PRIMARY KEY CLUSTERED,
Label VARCHAR(50) NOT NULL,
CONSTRAINT fkAncreLabel FOREIGN KEY (Id) REFERENCES velu.Ancre(Id),
ValidFrom datetime2(7) GENERATED ALWAYS AS ROW START NOT NULL,
ValidTo datetime2(7) GENERATED ALWAYS AS ROW END NOT NULL,
PERIOD FOR SYSTEM_TIME ([ValidFrom], [ValidTo])
)
WITH
(
SYSTEM_VERSIONING = ON ( HISTORY_TABLE = velu.AncreLabelHistory )
); -- Historisation du label
GO
CREATE TABLE velu.AncreAttribute
(
Id INT NOT NULL CONSTRAINT pkAncreAttribute PRIMARY KEY CLUSTERED,
Attribute VARCHAR(50) NOT NULL,
CONSTRAINT fkAncreAttribute FOREIGN KEY (Id) REFERENCES velu.Ancre(Id),
ValidFrom datetime2(7) GENERATED ALWAYS AS ROW START NOT NULL,
ValidTo datetime2(7) GENERATED ALWAYS AS ROW END NOT NULL,
PERIOD FOR SYSTEM_TIME ([ValidFrom], [ValidTo])
)
WITH
(
SYSTEM_VERSIONING = ON ( HISTORY_TABLE = velu.AncreAttributeHistory )
); -- Historisation de l'attribut
GO
CREATE TABLE velu.Condition
(
Id INT NOT NULL CONSTRAINT pkCondition PRIMARY KEY CLUSTERED,
Condition VARCHAR(50) NOT NULL
) -- Table de référence : Pas d'identity, pas d'historisation
GO
INSERT INTO velu.Condition(Id, Condition)
VALUES (1, 'En création'), (2, 'Validé'), (3, 'Archivé')
GO
CREATE TABLE velu.AncreCondition
(
AncreId INT NOT NULL CONSTRAINT fkAncreConditionAncreId FOREIGN KEY REFERENCES velu.Ancre(Id),
ConditionId INT NOT NULL CONSTRAINT fkAncreConditionConditionId FOREIGN KEY REFERENCES velu.Condition(Id),
ValidFrom datetime2(7) GENERATED ALWAYS AS ROW START NOT NULL,
ValidTo datetime2(7) GENERATED ALWAYS AS ROW END NOT NULL,
PERIOD FOR SYSTEM_TIME ([ValidFrom], [ValidTo]),
CONSTRAINT pkAncreCondition PRIMARY KEY CLUSTERED (AncreId, ConditionId)
)
WITH
(
SYSTEM_VERSIONING = ON ( HISTORY_TABLE = velu.AncreConditionHistory )
); -- historisation de l'état de l'ancre
GO
CREATE VIEW velu.vAncre
AS
SELECT a.Id, al.Label, att.Attribute, c.Condition, ac.ConditionId
FROM Ancre a
INNER JOIN AncreLabel al
ON al.Id = a.Id
LEFT JOIN AncreAttribute att
ON att.Id = a.Id
INNER JOIN AncreCondition ac
ON ac.AncreId = a.Id
INNER JOIN Condition c
ON c.Id = ac.ConditionId
GO
/****** Object: UserDefinedTableType [Reference].[tQuestion] Script Date: 03/03/2020 11:46:31 ******/
CREATE TYPE velu.tAncre AS TABLE(
Id INT NULL,
Label VARCHAR(50) NOT NULL,
Attribute VARCHAR(50) NULL,
ConditionId INT NOT NULL
)
GO
CREATE TRIGGER it_vAncre ON velu.vAncre
INSTEAD OF INSERT
AS
BEGIN
-- mettre ici différents tests éventuels
DECLARE @tAncre velu.tAncre;
INSERT INTO @tAncre(Id, Label, Attribute, ConditionId)
SELECT Id, Label, Attribute, ConditionId
FROM inserted;
EXEC velu.P_AncreMerge @tAncre = @tAncre, @ReturnResult = 0;
END
GO
CREATE PROCEDURE velu.P_AncreMerge
@tAncre velu.tAncre READONLY,
@ReturnResult bit = 1
AS
BEGIN
SET XACT_ABORT, NOCOUNT ON
BEGIN TRY
BEGIN TRANSACTION
DECLARE @MergedAncre velu.tAncre -- nouvelle table car @tAncre est readonly
-- Création des nouveaux Id pour les données à créer
MERGE INTO velu.Ancre t
USING @tAncre src
ON src.Id = t.Id
WHEN NOT MATCHED THEN
INSERT
DEFAULT VALUES
OUTPUT ISNULL(src.Id, inserted.Id), src.Label, src.Attribute, src.ConditionId INTO @MergedAncre;
-- Récupération des données à mettre à jour
INSERT INTO @MergedAncre
SELECT *
FROM @tAncre
WHERE Id IS NOT NULL
-- mise à jour des autres tables
MERGE INTO velu.AncreLabel t
USING @MergedAncre src
ON src.Id = t.Id
WHEN NOT MATCHED THEN
INSERT(Id, Label)
VALUES(src.Id, src.Label)
WHEN MATCHED THEN
UPDATE SET Label = src.Label;
MERGE INTO velu.AncreAttribute t
USING @MergedAncre src
ON src.Id = t.Id
WHEN NOT MATCHED AND src.Attribute IS NOT NULL THEN
INSERT(Id ,Attribute)
VALUES(src.Id, src.Attribute)
WHEN MATCHED AND src.Attribute IS NULL THEN
DELETE
WHEN MATCHED THEN
UPDATE SET Attribute = src.Attribute;
MERGE INTO velu.AncreCondition t
USING @MergedAncre src
ON src.Id = t.AncreId
WHEN NOT MATCHED THEN
INSERT(AncreId ,ConditionId)
VALUES(src.Id, src.ConditionId)
WHEN MATCHED THEN
UPDATE SET ConditionId = src.ConditionId;
IF @ReturnResult = 1
BEGIN
-- renvoie les données
SELECT *
FROM @MergedAncre
END
IF @@TRANCOUNT > 0 BEGIN COMMIT TRANSACTION END
END TRY
BEGIN CATCH
IF (XACT_STATE()) = -1
BEGIN
ROLLBACK TRANSACTION;
END;
THROW
END CATCH
END;
GO
INSERT INTO velu.vAncre(Label, Attribute, ConditionId)
VALUES( 'test1', NULL, 1), ('test2', 'blabla', 1);
select *
from velu.vAncre -- les données ont été insérées et sont visible dans ma vue
DECLARE @test velu.tAncre
INSERT INTO @test(Label, Attribute, ConditionId)
VALUES( 'test3', NULL, 1), ('test4', 'blabla', 1), ('test5', NULL, 1);
DECLARE @result velu.tAncre
INSERT INTO @result
EXEC velu.P_AncreMerge @tAncre = @test
SELECT *
FROM velu.vAncre -- les données ont été insérées et sont visible dans ma vue
SELECT *
FROM @Result -- je récupère les valeurs insérées pour un autre traitement (par exemple, insérer les Id des Ancres dans une autre table) |