Northwind Database (Document! X Sample)
AdventureWorks Database / Sales Schema / Sales.SalesOrderHeader Table / uSalesOrderHeader Trigger
In This Topic
    uSalesOrderHeader Trigger
    In This Topic
    Description
    AFTER UPDATE trigger that updates the RevisionNumber and ModifiedDate columns in the SalesOrderHeader table.Updates the SalesYTD column in the SalesPerson and SalesTerritory tables.
    Properties
    Creation Date27/10/2017 14:33
    Encrypted
    Ansi Nulls
    Trigger Type
    Insert Delete Update After Instead Of
    Trigger Definition
    CREATE TRIGGER [Sales].[uSalesOrderHeader] ON [Sales].[SalesOrderHeader] 
    AFTER UPDATE NOT FOR REPLICATION AS 
    
    BEGIN
        DECLARE @Count int;
    
        SET @Count = @@ROWCOUNT;
        IF @Count = 0 
            RETURN;
    
        SET NOCOUNT ON;
    
        BEGIN TRY
            -- Update RevisionNumber for modification of any field EXCEPT the Status.
            IF NOT UPDATE([Status])
            BEGIN
                UPDATE [Sales].[SalesOrderHeader]
                SET [Sales].[SalesOrderHeader].[RevisionNumber] = 
                    [Sales].[SalesOrderHeader].[RevisionNumber] + 1
                WHERE [Sales].[SalesOrderHeader].[SalesOrderID] IN 
                    (SELECT inserted.[SalesOrderID] FROM inserted);
            END;
    
            -- Update the SalesPerson SalesYTD when SubTotal is updated
            IF UPDATE([SubTotal])
            BEGIN
                DECLARE @StartDate datetime,
                        @EndDate datetime
    
                SET @StartDate = [dbo].[ufnGetAccountingStartDate]();
                SET @EndDate = [dbo].[ufnGetAccountingEndDate]();
    
                UPDATE [Sales].[SalesPerson]
                SET [Sales].[SalesPerson].[SalesYTD] = 
                    (SELECT SUM([Sales].[SalesOrderHeader].[SubTotal])
                    FROM [Sales].[SalesOrderHeader] 
                    WHERE [Sales].[SalesPerson].[BusinessEntityID] = [Sales].[SalesOrderHeader].[SalesPersonID]
                        AND ([Sales].[SalesOrderHeader].[Status] = 5) -- Shipped
                        AND [Sales].[SalesOrderHeader].[OrderDate] BETWEEN @StartDate AND @EndDate)
                WHERE [Sales].[SalesPerson].[BusinessEntityID] 
                    IN (SELECT DISTINCT inserted.[SalesPersonID] FROM inserted 
                        WHERE inserted.[OrderDate] BETWEEN @StartDate AND @EndDate);
    
                -- Update the SalesTerritory SalesYTD when SubTotal is updated
                UPDATE [Sales].[SalesTerritory]
                SET [Sales].[SalesTerritory].[SalesYTD] = 
                    (SELECT SUM([Sales].[SalesOrderHeader].[SubTotal])
                    FROM [Sales].[SalesOrderHeader] 
                    WHERE [Sales].[SalesTerritory].[TerritoryID] = [Sales].[SalesOrderHeader].[TerritoryID]
                        AND ([Sales].[SalesOrderHeader].[Status] = 5) -- Shipped
                        AND [Sales].[SalesOrderHeader].[OrderDate] BETWEEN @StartDate AND @EndDate)
                WHERE [Sales].[SalesTerritory].[TerritoryID] 
                    IN (SELECT DISTINCT inserted.[TerritoryID] FROM inserted 
                        WHERE inserted.[OrderDate] BETWEEN @StartDate AND @EndDate);
            END;
        END TRY
        BEGIN CATCH
            EXECUTE [dbo].[uspPrintError];
    
            -- Rollback any active or uncommittable transactions before
            -- inserting information in the ErrorLog
            IF @@TRANCOUNT > 0
            BEGIN
                ROLLBACK TRANSACTION;
            END
    
            EXECUTE [dbo].[uspLogError];
        END CATCH;
    END;
    
    See Also