Browse Source

DB Architecture Example

Kitt Parker 4 months ago
commit
eef2f49378
4 changed files with 211 additions and 0 deletions
  1. 93 0
      ContractTrigger.sql
  2. 47 0
      FieldTrackingTable.sql
  3. 71 0
      InvoiceTrigger.sql
  4. 0 0
      README.md

+ 93 - 0
ContractTrigger.sql

@@ -0,0 +1,93 @@
+CREATE OR ALTER TRIGGER trg_AfterInsert_JobSTATUS_FieldHistoryTracker
+ON FieldHistoryTracker
+AFTER INSERT
+AS
+BEGIN
+    SET NOCOUNT ON;
+    -- Update old records to set Active = 0 (False)
+    UPDATE w
+    SET w.Active = 0
+    FROM FieldHistoryTracker w
+    INNER JOIN inserted i 
+        ON w.CompanyID = i.CompanyID
+        AND w.RelatedKey = i.RelatedKey
+        AND w.FieldCode = i.FieldCode
+        where w.FieldCode in ('JOBSTATUS', 'INPROG', 'DISP')
+	and w.Id != i.Id
+        and i.Import = 0
+        AND w.Active = 1;
+End;
+
+GO
+
+CREATE OR ALTER TRIGGER _trg_Attention_After_Update_Insert_ContractKvExt
+ON ContractKvExt
+AFTER UPDATE, INSERT
+AS
+BEGIN
+    INSERT INTO FieldHistoryTracker (
+        CompanyID,
+        FieldCode,
+        KeyType,
+        RelatedKey,
+        UDF,
+        Active,
+        Import,
+        FieldDescription,
+        FieldValueCode,
+        FieldValueText,
+        AppliedDate,
+        AppliedByUserID,
+        AppliedByUserName,
+        LastModifiedDateTime,
+        LastModifiedByName,
+        LastModifiedByID
+    )
+    SELECT
+        c.CompanyID, 
+        cd.AttributeID,
+        'Contract',
+        c.ContractCD,
+        1,  -- UDF
+        1,  -- Active
+        0,  -- Import
+        ca.Description,
+        cd.ValueID, --Was not attributeID
+        cd.Description,
+        c.LastModifiedDateTime,
+        c.LastModifiedByID,
+        u.FullName,
+        c.LastModifiedDateTime,
+        u.FullName,
+        c.LastModifiedByID
+    FROM INSERTED i
+    LEFT JOIN DELETED d
+           ON d.CompanyID = i.CompanyID
+          AND d.RecordID  = i.RecordID
+          AND d.FieldName = i.FieldName
+    JOIN ContractKvExt cke 
+         ON i.CompanyID = cke.CompanyID 
+        AND i.RecordID  = cke.RecordID
+        AND i.FieldName = cke.FieldName
+    JOIN Contract c 
+         ON c.CompanyID = cke.CompanyID 
+        AND c.NoteID    = cke.RecordID
+    JOIN CSAttributeDetail cd 
+         ON cd.CompanyID    = cke.CompanyID
+        AND cke.ValueString = cd.ValueID
+    JOIN CSAttribute ca 
+         ON ca.CompanyID   = cd.CompanyID
+        AND ca.AttributeID = cd.AttributeID
+    JOIN Users u 
+         ON c.CompanyID = u.CompanyID
+        AND u.PKID      = c.LastModifiedByID
+    WHERE cd.AttributeID IN ('JOBSTATUS', 'INPROG')
+      AND (
+          -- 1) If there's no 'old' row (d.FieldName IS NULL), it's a new insert
+          d.FieldName IS NULL
+          OR
+          -- 2) If there's an old row, check if something truly changed
+          REPLACE(d.FieldName,'Attribute','') <> REPLACE(i.FieldName,'Attribute','')
+          OR d.ValueString <> i.ValueString
+      );
+END;

+ 47 - 0
FieldTrackingTable.sql

@@ -0,0 +1,47 @@
+CREATE TABLE AcumaticaDB.dbo.FieldHistoryTracker (
+	ID int IDENTITY(1,1) NOT NULL,
+	CompanyID int NOT NULL,
+	FieldCode nvarchar(50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
+	FieldCodeHash AS (abs(checksum([FieldCode]))%(10)) PERSISTED NOT NULL,
+	KeyType nvarchar(50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
+	RelatedKey nvarchar(50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL,
+	UDF bit DEFAULT 0 NOT NULL,
+	Active bit DEFAULT 0 NOT NULL,
+	Import bit DEFAULT 0 NULL,
+	FieldDescription nvarchar(255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
+	FieldValueCode nvarchar(50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
+	FieldValueText nvarchar(200) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
+	FieldValueDecimal decimal(18,6) NULL,
+	AppliedDate datetime NOT NULL,
+	AppliedbyUserID uniqueidentifier NULL,
+	AppliedbyUserName nvarchar(100) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
+	LastModifiedDateTime datetime NOT NULL,
+	LastModifiedByName nvarchar(100) COLLATE SQL_Latin1_General_CP1_CI_AS NULL,
+	LastModifiedByID uniqueidentifier NULL,
+	CONSTRAINT PK__Watterso__D435033A914A3CF4 PRIMARY KEY (FieldCodeHash,ID),
+	CONSTRAINT UQ__Watterso__47317D7CF73A082D UNIQUE (FieldCodeHash,FieldCode,CompanyID,ID)
+);
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_Active_UDF ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , CompanyID ASC  , Active ASC  , UDF ASC  , AppliedDate ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_AppliedByUser ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , AppliedbyUserID ASC  , AppliedbyUserName ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_AppliedByUser_Active ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , AppliedbyUserID ASC  , Active ASC  , AppliedDate ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_AppliedDate ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , AppliedDate ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_FieldCodeHash ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , FieldCode ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_FieldCodeValueType ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , FieldCode ASC  , FieldValueCode ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_FieldValue ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , FieldValueText ASC  , AppliedDate ASC  , AppliedbyUserID ASC  , AppliedbyUserName ASC  , Active ASC  , UDF ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;
+ CREATE NONCLUSTERED INDEX IX_FieldHistoryTracker_KeyType_RelatedKey ON AcumaticaDB.dbo.FieldHistoryTracker (  FieldCodeHash ASC  , KeyType ASC  , RelatedKey ASC  )  
+	 WITH (  PAD_INDEX = OFF ,FILLFACTOR = 100  ,SORT_IN_TEMPDB = OFF , IGNORE_DUP_KEY = OFF , STATISTICS_NORECOMPUTE = OFF , ONLINE = OFF , ALLOW_ROW_LOCKS = ON , ALLOW_PAGE_LOCKS = ON  )
+	 ON [PRIMARY ] ;

+ 71 - 0
InvoiceTrigger.sql

@@ -0,0 +1,71 @@
+CREATE OR ALTER TRIGGER _trg_Attention_After_Update_Insert_InvoiceKvExt
+ON ARRegisterKvExt
+AFTER UPDATE, INSERT
+AS
+BEGIN
+    INSERT INTO FieldHistoryTracker (
+        CompanyID,
+        FieldCode,
+        KeyType,
+        RelatedKey,
+        UDF,
+        Active,
+        Import,
+        FieldDescription,
+        FieldValueCode,
+        FieldValueText,
+        AppliedDate,
+        AppliedByUserID,
+        AppliedByUserName,
+        LastModifiedDateTime,
+        LastModifiedByName,
+        LastModifiedByID
+    )
+    SELECT
+        c.CompanyID, 
+        cd.AttributeID,
+        'Invoice',
+        c.RefNbr ,
+        1,  -- UDF
+        1,  -- Active
+        0,  -- Import
+        ca.Description,
+        cd.ValueID, --Was not attributeID
+        cd.Description,
+        c.LastModifiedDateTime,
+        c.LastModifiedByID,
+        u.FullName,
+        c.LastModifiedDateTime,
+        u.FullName,
+        c.LastModifiedByID
+    FROM INSERTED i
+    LEFT JOIN DELETED d
+           ON d.CompanyID = i.CompanyID
+          AND d.RecordID  = i.RecordID
+          AND d.FieldName = i.FieldName
+    JOIN ARRegisterKvExt cke 
+         ON i.CompanyID = cke.CompanyID 
+        AND i.RecordID  = cke.RecordID
+        AND i.FieldName = cke.FieldName
+    join ARRegister c
+         ON c.CompanyID = cke.CompanyID 
+        AND c.NoteID    = cke.RecordID
+    JOIN CSAttributeDetail cd 
+         ON cd.CompanyID    = cke.CompanyID
+        AND cke.ValueString = cd.ValueID
+    JOIN CSAttribute ca 
+         ON ca.CompanyID   = cd.CompanyID
+        AND ca.AttributeID = cd.AttributeID
+    JOIN Users u 
+         ON c.CompanyID = u.CompanyID
+        AND u.PKID      = c.LastModifiedByID
+    WHERE cd.AttributeID IN ('DISP')
+      AND (
+          -- 1) If there's no 'old' row (d.FieldName IS NULL), it's a new insert
+          d.FieldName IS NULL
+          OR
+          -- 2) If there's an old row, check if something truly changed
+          REPLACE(d.FieldName,'Attribute','') <> REPLACE(i.FieldName,'Attribute','')
+          OR d.ValueString <> i.ValueString
+      );
+END;

+ 0 - 0
README.md