• Nadrek (10/2/2009)


    [Database level constraints are the best way I know of to limit issues from happening; whether they're function based and expensive [...]

    Agreed, and there have been comments woven through the thread so far, that effective dates are expensive, ditto for any constraint that is difficult to suborn.

    If commercial reality, or in other words, keeping your job, means taking shortcuts, then it's up to the DBA to recommend spending the immediately available budget on the lower total cost constraints and document the exposure involved in not implementing the higher total cost constraints.

    It's then up to the CxO's to determine the total cost to the business of not implementing the higher total cost constraints, and carry the responsibility for the risk.

    If you have no authority for the budget, you have no responsibility for those extraneous costs, after you've made the recommendations that fall within generally agreed best practice.

    But then "generally agreed best practice" is a whole other can of worms.

    Back on to topic, here's some fragments that I exhumed from the archive of one of my succesful SQL2000 projects. Yes, I have had my share of unsuccessful projects. Doh.

    As I don't write nearly as well, nor as clearly, as Sam Bendayan, this response from here on, isn't pitched to those fairly new to the industry, only to those that won't hesitate to tear me to shreds, eh REBAR.

    The gist of this project is that a "record" is represented by a [DomainId], the temporally unique aspect of the record is represented by the [Id], within the [DomainId]. There were a huge number of auditability constraints placed on the project. In order to work with the auditability and the outrageous expense of temporal consistancy at any -specified- point in time, not just now, the logic was based on shortest path for most frequently used requests, hence the exception logic may be drawn out and regardless of that, a -substantial- amount of horsepower was in use to run the production systems.

    The five fragments are for a CREATE TABLE, the INSTEAD OF INSERT trigger, the INSTEAD OF UPDATE trigger, a SET procedure to do INSERT, UPDATE and DELETE, and a GET scalar procedure. These should give a pretty good overview of how the temporal management aspects of the project came together, without worrying about the auditability and reporting, which moved out of SQL and into web services and proprietary products.

    Horses, for courses, as long as -all- the data is there, and the integrity is ensured, I have no problem with positively bizarre business rules being implemented for RO off the database and on the application servers.

    The project database stored batched transactional data from various revenue generating machines, a CRM structure for multiple companies owning subsets of the machines, which were occasionally sold between organisations (no, no, no, I did not want to do this), and batched OLAP denormalisations where the DBMS simply could not cope with a report structure across the temporal and organisational structure.

    Some of what I did with this project, I would love to redo with SQL2008, particularly using the advances in DATE and TIME handling and using CLR, although I still have a bad feeling about some of the performance issues in that area.

    As this code was dug off CD and isn't recent production code, any errors are entirely mine, incurred during coding, and I should be lambasted for them.

    /* -------------------------------------------------------------------

    Table

    MachineDomain

    Documentation

    Project: thisProject

    Aspect: Core

    Prepared by: thisOrganisationalUnit

    For: thatOrganistionalUnit

    Description

    Stores the descriptor for each machine to be supported by the

    suite.

    The [Serial] column is an alias for the [Id] and is a unique

    serial number from the manufacturer. Join to the record on the

    [Id], not the [Serial].

    -----------------------------------------------------------------*/

    CREATE TABLE [dbo].[MachineDomain]

    (

    [Active] [datetime] NULL,

    [Archive] [datetime] NULL,

    [ArchiveInsert] [datetime] NULL,

    [AuditReferenceInsert] [uniqueidentifier] NULL,

    [AuditReferenceUpdate] [uniqueidentifier] NULL,

    [Description] [nvarchar] (900) NULL,

    [DomainId] [int] NOT NULL IDENTITY(1, 1),

    [Id] [int] NULL,

    [ModelCategoryDomainId] [int] NOT NULL,

    [Name] [nvarchar] (450) NOT NULL,

    [Serial] [nchar] (24) NULL

    )

    ON [PRIMARY]

    GO

    /* -------------------------------------------------------------------

    Trigger

    MachineDomainInsteadOfInsert

    Documentation

    Project: thisProject

    Aspect: Core

    Prepared by: thisOrganisationalUnit

    For: thatOrganistionalUnit

    -----------------------------------------------------------------*/

    ALTER TRIGGER [MachineDomainInsteadOfInsert]

    ON [dbo].[MachineDomain]

    INSTEAD OF INSERT AS

    BEGIN

    SET NOCOUNT ON

    DECLARE @Active [datetime]

    DECLARE @AccountId [int]

    DECLARE @archive [datetime]

    DECLARE @AuditCategoryId [int]

    DECLARE @AuditReferenceInsert [uniqueidentifier]

    DECLARE @AuditReferenceUpdate [uniqueidentifier]

    DECLARE @Count [int]

    DECLARE @CurrentTimestamp [datetime]

    DECLARE @DomainId [int]

    DECLARE @Error [int]

    DECLARE @MaximumTimestamp [datetime]

    DECLARE @MessageAlias [nchar] (24)

    DECLARE @MessageObject [nvarchar] (450)

    DECLARE @MessageText [nvarchar] (400)

    DECLARE @Return [int]

    /* -------------------------------------------------------------------

    Get constants.

    ------------------------------------------------------------------- */

    SET @MessageObject = LOWER(N'['+@@SERVERNAME+N'].['+DB_NAME()+N'].['+SESSION_USER+N'].['+OBJECT_NAME(@@PROCID)+N']')

    /* -------------------------------------------------------------------

    INSERT multiple records in a single batch is not supported.

    ------------------------------------------------------------------- */

    SELECT

    @Count = COUNT(*)

    FROM

    INSERTED

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56301'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    IF (@Count = 0)

    BEGIN

    SET @MessageAlias = N'TOU56302'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    IF (@Count > 1)

    BEGIN

    SET @MessageAlias = N'TOU56303'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    /* -------------------------------------------------------------------

    Get values from the INSERTED table that will be referenced several

    times in the following checking

    ------------------------------------------------------------------- */

    SET @Active = NULL

    SET @archive = NULL

    SET @AuditReferenceInsert = NULL

    SELECT

    @Active = [Active],

    @archive = [Archive],

    @AuditReferenceInsert = [AuditReferenceInsert]

    FROM

    INSERTED

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56304'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    /* -------------------------------------------------------------------

    Check the session token is current and a valid account is

    executing the trigger.

    ------------------------------------------------------------------- */

    SET @Return = NULL

    EXECUTE @Return = [dbo].[CheckAccess]

    @AccountId = @AccountId OUTPUT,

    @AuditAccessAlias = N'INSERT',

    @AuditCategoryAlias = N'MACHINE',

    @AuditCategoryId = @AuditCategoryId OUTPUT,

    @AuditDatabaseReference = @AuditReferenceUpdate OUTPUT,

    @CurrentTimestamp = @CurrentTimestamp OUTPUT,

    @MaximumTimestamp = @MaximumTimestamp OUTPUT,

    @MessageAlias = @MessageAlias OUTPUT,

    @Reference = @AuditReferenceInsert

    SET @Error = @@ERROR

    IF (@Error <> 0 OR @Return IS NULL OR @Return <> 0)

    BEGIN

    SET @MessageAlias = ISNULL(LTRIM(RTRIM(@MessageAlias)),N'TOU59998')

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR, LOG

    RETURN

    END

    /* -------------------------------------------------------------------

    Set default values if not supplied on the INSERTED record.

    ------------------------------------------------------------------- */

    SET @Active = ISNULL(@Active, @CurrentTimestamp)

    SET @archive = ISNULL(@Archive, @MaximumTimestamp)

    /* -------------------------------------------------------------------

    Check there is no inconsistant temporal overlap.

    ------------------------------------------------------------------- */

    IF (@Active < @CurrentTimestamp)

    BEGIN

    SET @MessageAlias = N'TOU56305'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    IF (@Archive < @Active)

    BEGIN

    SET @MessageAlias = N'TOU56306'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    /* -------------------------------------------------------------------

    Check the new descriptor is unique. If it isn't unique it will

    require an UPDATE not an INSERT.

    ------------------------------------------------------------------- */

    BEGIN

    IF EXISTS

    (

    SELECT

    *

    FROM

    [dbo].[MachineDomain] AS [MachineDomain]

    INNER JOIN INSERTED AS [Inserted]

    ON [MachineDomain].[Name] = [Inserted].[Name]

    )

    BEGIN

    SET @MessageAlias = N'TOU56307'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,N'[Name]')

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    BEGIN

    IF EXISTS

    (

    SELECT

    *

    FROM

    [dbo].[MachineDomain] AS [MachineDomain]

    INNER JOIN INSERTED AS [Inserted]

    ON [MachineDomain].[Serial] = [Inserted].[Serial]

    )

    BEGIN

    SET @MessageAlias = N'TOU56307'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,N'[Serial]')

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    /* -------------------------------------------------------------------

    INSERT the new record.

    ------------------------------------------------------------------- */

    INSERT [dbo].[MachineDomain]

    (

    [Active],

    [Archive],

    [ArchiveInsert],

    [AuditReferenceInsert],

    [AuditReferenceUpdate],

    [Description],

    [ModelCategoryDomainId],

    [Name],

    [Serial]

    )

    SELECT

    @Active,

    @archive,

    @archive,

    @AuditReferenceInsert,

    @AuditReferenceUpdate,

    [Description],

    [ModelCategoryDomainId],

    [Name],

    [Serial]

    FROM

    INSERTED AS [Inserted]

    SET @Error = @@ERROR

    SET @DomainId = SCOPE_IDENTITY()

    IF (@Error <> 0 OR @DomainId IS NULL OR @DomainId = 0)

    BEGIN

    SET @MessageAlias = N'TOU56309'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    UPDATE [dbo].[MachineDomain]

    SET[Id] = @DomainId

    WHERE [DomainId] = @DomainId

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56310'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    GO

    /* -------------------------------------------------------------------

    Trigger

    MachineDomainInsteadOfUpdate

    Documentation

    Project: thisProject

    Aspect: Core

    Prepared by: thisOrganisationalUnit

    For: thatOrganistionalUnit

    -----------------------------------------------------------------*/

    ALTER TRIGGER [MachineDomainInsteadOfUpdate]

    ON [dbo].[MachineDomain]

    INSTEAD OF UPDATE AS

    BEGIN

    SET NOCOUNT ON

    DECLARE @AccountId [int]

    DECLARE @AuditAccessAlias [nchar] (24)

    DECLARE @AuditCategoryId [int]

    DECLARE @AuditDatabaseReference [uniqueidentifier]

    DECLARE @Count [int]

    DECLARE @CountDistinct [int]

    DECLARE @CurrentTimestamp [datetime]

    DECLARE @DefaultAuditReferenceUpdate [uniqueidentifier]

    DECLARE @DeletedActive [datetime]

    DECLARE @DeletedArchive [datetime]

    DECLARE @DeletedAuditReferenceInsert [uniqueidentifier]

    DECLARE @DeletedAuditReferenceUpdate [uniqueidentifier]

    DECLARE @DeletedDomainId [int]

    DECLARE @DeletedId [int]

    DECLARE @Error [int]

    DECLARE @InsertedActive [datetime]

    DECLARE @InsertedArchive [datetime]

    DECLARE @InsertedAuditReferenceInsert [uniqueidentifier]

    DECLARE @InsertedAuditReferenceUpdate [uniqueidentifier]

    DECLARE @MaximumTimestamp [datetime]

    DECLARE @MessageAlias [nchar] (24)

    DECLARE @MessageObject [nvarchar] (450)

    DECLARE @MessageText [nvarchar] (400)

    DECLARE @Return [int]

    DECLARE @ReturnDomainId [int]

    /* -------------------------------------------------------------------

    Get constants

    ------------------------------------------------------------------- */

    SET @MessageObject = LOWER(N'['+@@SERVERNAME+N'].['+DB_NAME()+N'].['+SESSION_USER+N'].['+OBJECT_NAME(@@PROCID)+N']')

    /* -------------------------------------------------------------------

    UPDATE multiple records in a single batch is not supported,

    however UPDATE is allowed by specifying the [DomainId] or [Id] of

    the record.

    If the [DomainId] is specified on the UPDATE constraint, it must

    be the currently active record of the [Id] group.

    If the [Id] is specified on the UPDATE constraint, multiple

    records may be SELECTed but only the currently active record from

    the [Id] group will be UPDATEd.

    ------------------------------------------------------------------- */

    SELECT

    @Count = COUNT(*)

    FROM

    INSERTED

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56301'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    IF (@Count = 0)

    BEGIN

    SET @MessageAlias = N'TOU56302'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    IF (@Count > 1)

    BEGIN

    SELECT

    @CountDistinct = COUNT(DISTINCT [Id])

    FROM

    INSERTED

    SET @Error = @@ERROR

    IF (@Error <> 0 OR @CountDistinct > 1)

    BEGIN

    SET @MessageAlias = N'TOU56303'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    /* -------------------------------------------------------------------

    Get values from the DELETED and INSERTED tables that will be

    referenced several times in the following checking.

    As a consequence of allowing UPDATE based on [DomainId] or [Id],

    [AuditDatabaseStatic].[Reference] has to be included in the

    SELECT here, rather than waiting for it to be returned from the

    call to [CheckAccess] as happens in the INSERT triggers and all

    other procedures, so that the correct record can be retrieved.

    ------------------------------------------------------------------- */

    SELECT

    @DeletedActive = [Deleted].[Active],

    @DeletedArchive = [Deleted].[Archive],

    @DeletedAuditReferenceInsert = [Deleted].[AuditReferenceInsert],

    @DeletedAuditReferenceUpdate = [Deleted].[AuditReferenceUpdate],

    @DeletedDomainId = [Deleted].[DomainId],

    @DeletedId = [Deleted].[Id],

    @InsertedActive = [Inserted].[Active],

    @InsertedArchive = [Inserted].[Archive],

    @InsertedAuditReferenceInsert = [Inserted].[AuditReferenceInsert],

    @InsertedAuditReferenceUpdate = [Inserted].[AuditReferenceUpdate]

    FROM

    DELETED AS [Deleted]

    INNER JOIN INSERTED AS [Inserted]

    ON [Deleted].[DomainId] = [Inserted].[DomainId]

    INNER JOIN [dbo].[AuditDatabaseStatic] AS [AuditDatabase]

    ON [Deleted].[AuditReferenceUpdate] = [AuditDatabase].[Reference]

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56311'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    /* -------------------------------------------------------------------

    Check the session token is current and a valid account is changing

    the record.

    ------------------------------------------------------------------- */

    SET @Return = NULL

    EXECUTE @Return = [dbo].[CheckAccess]

    @AccountId = @AccountId OUTPUT,

    @AuditAccessAlias = N'UPDATE',

    @AuditCategoryAlias = N'MACHINE',

    @AuditCategoryId = @AuditCategoryId OUTPUT,

    @AuditDatabaseReference = @AuditDatabaseReference OUTPUT,

    @CurrentTimestamp = @CurrentTimestamp OUTPUT,

    @MaximumTimestamp = @MaximumTimestamp OUTPUT,

    @MessageAlias = @MessageAlias OUTPUT,

    @Reference = @InsertedAuditReferenceUpdate

    SET @Error = @@ERROR

    IF (@Error <> 0 OR @Return IS NULL OR @Return <> 0)

    BEGIN

    SET @MessageAlias = ISNULL(LTRIM(RTRIM(@MessageAlias)),N'TOU59998')

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR, LOG

    RETURN

    END

    /* -------------------------------------------------------------------

    Check for the [Active] datetime being set to NULL or copied from

    the DELETEd table and replace it with @CurrentTimestamp plus the

    minimum supported milliseconds.

    ------------------------------------------------------------------- */

    IF (@InsertedActive IS NULL OR @InsertedActive = @DeletedActive)

    SET @InsertedActive = DATEADD(MILLISECOND, +2, @CurrentTimestamp)

    /* -------------------------------------------------------------------

    This is an obscure piece of logic that makes no sense on the

    surface, it is implemented to allow a record [Archive] to be

    set to [dbo].[CurrentTimestamp]() to effectively delete the record.

    The InsteadOfDelete trigger can't be used for a delete because

    the new [AuditReferenceUpdate] can't be passed on the delete

    statement, so no audit path can be maintained.

    To allow for latency between the call to UPDATE and the actual

    UPDATE occurring affecting the value of [dbo].[CurrentTimestamp](),

    there is a rule implemented that if INSERTED.[Archive] is

    DELETED.[Active] plus 2 milliseconds, the request is a

    DELETE and [Archive] will be set to [dbo].[CurrentTimestamp]().

    The [AuditReferenceUpdate] is left as the default value so

    the record can be undeleted again by an update with an

    [Archive] later than [dbo].[CurrentTimestamp]().

    ------------------------------------------------------------------- */

    IF (DATEADD(MILLISECOND, +2, @DeletedActive) = @InsertedArchive)

    BEGIN

    SET @InsertedArchive = DATEADD(MILLISECOND, +2, @InsertedActive)

    IF (DATEADD(MILLISECOND, -2, @InsertedActive) > @DeletedArchive AND @DeletedAuditReferenceUpdate = @AuditDatabaseReference)

    BEGIN

    SET @MessageAlias = N'TOU56312'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    /* -------------------------------------------------------------------

    Check the [Archive] datetime being set to NULL or being copied

    from the DELETEd table and replace it with @MaximumTimestamp.

    ------------------------------------------------------------------- */

    IF (@InsertedArchive IS NULL OR @InsertedArchive = @DeletedArchive)

    SET @InsertedArchive = @MaximumTimestamp

    /* -------------------------------------------------------------------

    Check there is no inconsistant temporal overlap.

    ------------------------------------------------------------------- */

    IF (@InsertedActive < @CurrentTimestamp)

    BEGIN

    SET @MessageAlias = N'TOU56305'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    IF (@InsertedArchive < @InsertedActive)

    BEGIN

    SET @MessageAlias = N'TOU56306'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    IF (@InsertedActive < @DeletedActive)

    BEGIN

    SET @MessageAlias = N'TOU56313'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    /* -------------------------------------------------------------------

    Check the [Active] and [Archive] dates for discontiguous ranges

    and don't enforce contiguousness if it isn't there.

    ------------------------------------------------------------------- */

    IF (@DeletedArchive >= @InsertedActive)

    BEGIN

    SET @DeletedArchive = DATEADD(MILLISECOND, -2, @InsertedActive)

    END

    /* -------------------------------------------------------------------

    Check the new descriptor is unique across records other than the

    currently active [Id] group.

    ------------------------------------------------------------------- */

    BEGIN

    IF EXISTS

    (

    SELECT

    *

    FROM

    [dbo].[MachineDomain] AS [MachineDomain],

    INSERTED AS [Inserted]

    WHERE

    [MachineDomain].[Id] <> @DeletedId

    AND [MachineDomain].[Name] = [Inserted].[Name]

    )

    BEGIN

    SET @MessageAlias = N'TOU56314'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,N'[Name]')

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    BEGIN

    IF EXISTS

    (

    SELECT

    *

    FROM

    [dbo].[MachineDomain] AS [MachineDomain],

    INSERTED AS [Inserted]

    WHERE

    [MachineDomain].[Id] <> @DeletedId

    AND [MachineDomain].[Serial] = [Inserted].[Serial]

    )

    BEGIN

    SET @MessageAlias = N'TOU56314'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,N'[Serial]')

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    /* -------------------------------------------------------------------

    Updating a record to be a duplicate of itself is not supported

    except when a DELETE is being executed or a deleted record is

    being undeleted.

    ------------------------------------------------------------------- */

    IF NOT (@InsertedArchive = DATEADD(MILLISECOND, +2, @InsertedActive))

    BEGIN

    IF EXISTS

    (

    SELECT

    *

    FROM

    DELETED AS [Deleted]

    INNER JOIN INSERTED AS [Inserted]

    ON [Deleted].[DomainId] = [Inserted].[DomainId]

    WHERE

    [Deleted].[AuditReferenceUpdate] = @AuditDatabaseReference

    AND [Deleted].[Archive] >= @CurrentTimestamp

    AND ISNULL([Deleted].[Description], 0) = ISNULL(ISNULL([Inserted].[Description], [Deleted].[Description]), 0)

    AND [Deleted].[ModelCategoryDomainId] = ISNULL([Inserted].[ModelCategoryDomainId], [Deleted].[ModelCategoryDomainId])

    AND [Deleted].[Name] = ISNULL([Inserted].[Name], [Deleted].[Name])

    AND ISNULL([Deleted].[Serial], 0) = ISNULL(ISNULL([Inserted].[Serial], [Deleted].[Serial]), 0)

    )

    BEGIN

    SET @MessageAlias = N'TOU56315'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    /* -------------------------------------------------------------------

    UPDATE the archive timestamp for the existing record then INSERT

    the new record.

    ------------------------------------------------------------------- */

    UPDATE [dbo].[MachineDomain]

    SET

    [Archive] = @DeletedArchive,

    [AuditReferenceUpdate] = @InsertedAuditReferenceUpdate

    WHERE

    [DomainId] = @DeletedDomainId

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56316'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,N'[MachineId]')

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    INSERT [dbo].[MachineDomain]

    (

    [Active],

    [Archive],

    [ArchiveInsert],

    [AuditReferenceInsert],

    [AuditReferenceUpdate],

    [Description],

    [Id],

    [ModelCategoryDomainId],

    [Name],

    [Serial]

    )

    SELECT

    @InsertedActive,

    @InsertedArchive,

    @DeletedArchive,

    @InsertedAuditReferenceUpdate,

    @AuditDatabaseReference,

    [Description],

    @DeletedId,

    [ModelCategoryDomainId],

    [Name],

    [Serial]

    FROM

    INSERTED

    WHERE

    [DomainId] = @DeletedDomainId

    SET @Error = @@ERROR

    SET @ReturnDomainId = SCOPE_IDENTITY()

    IF (@Error <> 0 OR @ReturnDomainId IS NULL OR @ReturnDomainId = 0)

    BEGIN

    SET @MessageAlias = N'TOU56317'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,N'[MachineId]')

    RAISERROR (@MessageText,10,1) WITH SETERROR

    RETURN

    END

    END

    GO

    /* -------------------------------------------------------------------

    Procedure

    SetMachine

    Documentation

    Project: thisProject

    Aspect: Core

    Prepared by: thisOrganisationalUnit

    For: thatOrganistionalUnit

    Description

    Insert a record into the [Audit] table, then delete, insert or

    update a record in the [Machine] table.

    -----------------------------------------------------------------*/

    CREATE PROCEDURE [SetMachine]

    (

    @Active [datetime] = NULL,

    @archive [datetime] = NULL,

    @CategoryId [int] = NULL, -- For compatibility only, use @ModelCategoryId

    @Description [nvarchar] (900) = NULL,

    @Id [int] = NULL OUTPUT,

    @ModelCategoryId [int] = NULL,

    @Name [nvarchar] (450) = NULL,

    @Serial [nvarchar] (24) = NULL,

    @Token [nchar] (36) = NULL

    )

    AS

    BEGIN

    SET NOCOUNT ON

    DECLARE @AccountId [int]

    DECLARE @AuditCategoryId [int]

    DECLARE @AuditDatabaseReference [uniqueidentifier]

    DECLARE @CurrentTimestamp [datetime]

    DECLARE @Error [int]

    DECLARE @MaximumTimestamp [datetime]

    DECLARE @MessageAlias [nchar] (24)

    DECLARE @MessageObject [nvarchar] (450)

    DECLARE @MessageText [nvarchar] (400)

    DECLARE @ParameterActive [datetime]

    DECLARE @ParameterArchive [datetime]

    DECLARE @ParameterDescription [nvarchar] (900)

    DECLARE @ParameterId [int]

    DECLARE @ParameterModelCategoryId [int]

    DECLARE @ParameterName [nvarchar] (450)

    DECLARE @ParameterSerial [nvarchar] (24)

    DECLARE @Reference [uniqueidentifier]

    DECLARE @Return [int]

    DECLARE @ThisId [int]

    DECLARE @Transaction [nchar] (36)

    /* -------------------------------------------------------------------

    Get constants.

    ------------------------------------------------------------------- */

    SET @MessageObject = LOWER(N'['+@@SERVERNAME+N'].['+DB_NAME()+N'].['+SESSION_USER+N'].['+OBJECT_NAME(@@PROCID)+N']')

    SET @Reference = NEWID()

    SET @Transaction = CAST(@Reference AS [nchar] (36))

    /* -------------------------------------------------------------------

    Check the session token is current and a valid account is

    executing the procedure.

    ------------------------------------------------------------------- */

    SET @Return = NULL

    EXECUTE @Return = [dbo].[CheckAccess]

    @AccountId = @AccountId OUTPUT,

    @AuditAccessAlias = N'SET',

    @AuditCategoryAlias = N'MACHINE',

    @AuditCategoryId = @AuditCategoryId OUTPUT,

    @AuditDatabaseReference = @AuditDatabaseReference OUTPUT,

    @CurrentTimestamp = @CurrentTimestamp OUTPUT,

    @MaximumTimestamp = @MaximumTimestamp OUTPUT,

    @MessageAlias = @MessageAlias OUTPUT,

    @Token = @Token

    SET @Error = @@ERROR

    IF (@Error <> 0 OR @Return IS NULL OR @Return <> 0)

    BEGIN

    SET @MessageAlias = ISNULL(LTRIM(RTRIM(@MessageAlias)),N'TOU59998')

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERROR

    END

    /* -------------------------------------------------------------------

    Parse the parameters.

    ------------------------------------------------------------------- */

    SET @ParameterActive = @Active

    SET @ParameterArchive = ISNULL(@Archive,@MaximumTimestamp)

    SET @ParameterDescription = CASE LTRIM(RTRIM(@Description)) WHEN N'' THEN NULL ELSE LTRIM(RTRIM(@Description)) END

    SET @ParameterId = ISNULL(@Id, 0)

    SET @ParameterModelCategoryId = ISNULL(@ModelCategoryId, 0)

    IF (ISNULL(@CategoryId,0) <> 0)

    BEGIN

    SET @ParameterModelCategoryId = @CategoryId

    END

    SET @ParameterName = CASE LTRIM(RTRIM(@Name)) WHEN N'' THEN NULL ELSE LTRIM(RTRIM(@Name)) END

    /* -------------------------------------------------------------------

    Start the transaction

    ------------------------------------------------------------------- */

    BEGIN TRANSACTION @Transaction

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56526'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERROR

    END

    BEGIN

    /* -------------------------------------------------------------------

    Insert an audit record.

    ------------------------------------------------------------------- */

    INSERT [dbo].[AuditTransaction]

    (

    [AuditCategoryId],

    [Reference],

    [SessionId]

    )

    SELECT

    @AuditCategoryId,

    @Reference,

    [Id]

    FROM

    [dbo].[Session](@CurrentTimestamp)

    WHERE

    [Reference] = CAST(@Token AS [uniqueidentifier])

    SET @Error = @@ERROR

    SET @ThisId = @@IDENTITY

    IF (@Error <> 0 OR @ThisId IS NULL OR @ThisId = 0)

    BEGIN

    SET @MessageAlias = N'TOU56538'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    /* -------------------------------------------------------------------

    Is the request a DELETE, INSERT or UPDATE

    ------------------------------------------------------------------- */

    IF (@ParameterId <> 0 AND @ParameterDescription IS NULL AND @ParameterModelCategoryId = 0 AND @ParameterName IS NULL AND @ParameterSerial IS NULL)

    GOTO labelDELETE

    IF (@ParameterId = 0 AND @ParameterModelCategoryId <> 0 AND @ParameterName IS NOT NULL AND @ParameterSerial IS NOT NULL)

    GOTO labelINSERT

    IF (@ParameterId <> 0 AND @ParameterSerial IS NULL AND (@ParameterDescription IS NOT NULL OR @ParameterModelCategoryId <> 0 OR @ParameterName IS NOT NULL))

    GOTO labelUPDATE

    BEGIN

    SET @MessageAlias = N'TOU56061'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    /* -------------------------------------------------------------------

    DELETE updates the [Archive] datetime to now which effectively

    deletes the record while maintaining temporal integrity. If the

    @archive parameter has been set to greater than now, it will be

    used to allow a post-dated delete.

    The InsteadOfDelete trigger can't be used for a delete because the

    new [AuditReferenceUpdate] can't be passed on the delete statement,

    so no audit path can be maintained.

    So there is a rule implemented that if the InsteadOfUpdate trigger

    DELETED.[Archive] is INSERTED.[Active] plus 2 milliseconds, the

    request is a DELETE and [Archive] will be set to now.

    The [AuditReferenceUpdate] is left as the default value so the

    record can be undeleted again by an update with an [Archive] later

    than now.

    ------------------------------------------------------------------- */

    labelDELETE: BEGIN

    IF (@ParameterArchive IS NULL OR @ParameterArchive = @MaximumTimestamp)

    BEGIN

    SET @ParameterArchive = NULL

    SELECT

    @ParameterArchive = DATEADD(MILLISECOND, +2, [Active])

    FROM

    [dbo].[MachineDomain]

    WHERE

    [Id] = @ParameterId

    AND [AuditReferenceUpdate] = @AuditDatabaseReference

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56539'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    IF (@ParameterArchive IS NULL)

    BEGIN

    SET @MessageAlias = N'TOU56063'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    END

    UPDATE

    [dbo].[MachineDomain]

    SET

    [Archive] = @ParameterArchive,

    [AuditReferenceUpdate] = @Reference

    WHERE

    [Id] = @ParameterId

    SET @Error = @@ERROR

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56540'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    GOTO labelCHANGEDONE

    END

    /* -------------------------------------------------------------------

    INSERT a new record

    ------------------------------------------------------------------- */

    labelINSERT: BEGIN

    INSERT [dbo].[MachineDomain]

    (

    [Active],

    [Archive],

    [AuditReferenceInsert],

    [Description],

    [ModelCategoryDomainId],

    [Name],

    [Serial]

    )

    VALUES

    (

    @ParameterActive,

    @ParameterArchive,

    @Reference,

    @ParameterDescription,

    @ParameterModelCategoryId,

    @ParameterName,

    @ParameterSerial

    )

    SET @Error = @@ERROR

    SET @ParameterId = @@IDENTITY

    IF (@Error <> 0 OR @ParameterId IS NULL OR @ParameterId = 0)

    BEGIN

    SET @MessageAlias = N'TOU56541'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    GOTO labelCHANGEDONE

    END

    /* -------------------------------------------------------------------

    UPDATE an existing record

    ------------------------------------------------------------------- */

    labelUPDATE: BEGIN

    UPDATE

    [dbo].[MachineDomain]

    SET

    [Active] = @ParameterActive,

    [Archive] = @ParameterArchive,

    [AuditReferenceUpdate] = @Reference,

    [Description] = CASE WHEN @ParameterDescription IS NOT NULL THEN @ParameterDescription ELSE [Description] END,

    [ModelCategoryDomainId] = CASE WHEN @ParameterModelCategoryId <> 0 THEN @ParameterModelCategoryId ELSE [ModelCategoryDomainId] END,

    [Name] = CASE WHEN @ParameterName IS NOT NULL THEN @ParameterName ELSE [Name] END

    WHERE

    [Id] = @ParameterId

    SET @Error = @@ERROR

    IF @Error <> 0

    BEGIN

    SET @MessageAlias = N'TOU56542'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    GOTO labelCHANGEDONE

    END

    /* -------------------------------------------------------------------

    END transaction, COMMIT the changes

    ------------------------------------------------------------------- */

    END

    labelCHANGEDONE: BEGIN

    COMMIT TRANSACTION @Transaction

    SET @Error = @@ERROR

    IF @Error <> 0

    BEGIN

    SET @MessageAlias = N'TOU56527'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORINTRANSACTION

    END

    SET @Id = @ParameterId

    RETURN 0

    END

    /* -------------------------------------------------------------------

    Error termination routines.

    ------------------------------------------------------------------- */

    labelERRORINTRANSACTION: BEGIN

    ROLLBACK TRANSACTION @Transaction

    GOTO labelERROR

    END

    labelERROR: BEGIN

    SET @Id = NULL

    RAISERROR (@MessageText,10,1)

    RETURN CAST(RIGHT(LTRIM(RTRIM(@MessageAlias)),5) AS [int])

    END

    END

    GO

    /* -------------------------------------------------------------------

    Procedure

    GetMachine

    Documentation

    Project: thisProject

    Aspect: Core

    Prepared by: thisOrganisationalUnit

    For: thatOrganistionalUnit

    Description

    Get a resultset from the [Machine] table.

    @Serial is an alias for the [Id] and is a unique serial number

    from the manufacturer.

    -----------------------------------------------------------------*/

    CREATE PROCEDURE [GetMachine]

    (

    @Active [datetime] = NULL,

    @AuditId [int] = NULL,

    @Id [int] = NULL OUTPUT,

    @Name [nvarchar] (450) = NULL,

    @Serial [nvarchar] (24) = NULL,

    @Token [nchar] (36) = NULL

    )

    AS

    BEGIN

    SET NOCOUNT ON

    DECLARE @AccountId [int]

    DECLARE @Error [int]

    DECLARE @Location [nvarchar] (450)

    DECLARE @MessageAlias [nchar] (24)

    DECLARE @MessageObject [nvarchar] (450)

    DECLARE @MessageText [nvarchar] (400)

    DECLARE @ParameterActive [datetime]

    DECLARE @ParameterAuditId [int]

    DECLARE @ParameterId [int]

    DECLARE @ParameterName [nvarchar] (450)

    DECLARE @ParameterSerial [nvarchar] (24)

    DECLARE @Return [int]

    DECLARE @RowCount [int]

    /* -------------------------------------------------------------------

    Get constants.

    ------------------------------------------------------------------- */

    SET @MessageObject = LOWER(N'['+@@SERVERNAME+N'].['+DB_NAME()+N'].['+SESSION_USER+N'].['+OBJECT_NAME(@@PROCID)+N']')

    /* -------------------------------------------------------------------

    Parse the parameters

    ------------------------------------------------------------------- */

    SET @ParameterActive = @Active

    SET @ParameterAuditId = @AuditId

    SET @ParameterId = ISNULL(@Id, 0)

    SET @ParameterName = CASE LTRIM(RTRIM(@Name)) WHEN N'' THEN NULL ELSE LTRIM(RTRIM(@Name)) END

    SET @ParameterSerial = CASE LTRIM(RTRIM(@Serial)) WHEN N'' THEN NULL ELSE LTRIM(RTRIM(@Serial)) END

    /* -------------------------------------------------------------------

    Check the combination of parameters

    ------------------------------------------------------------------- */

    IF (@ParameterId <> 0 AND @ParameterName IS NULL AND @ParameterSerial IS NULL)

    GOTO labelOK

    IF (@ParameterId = 0 AND @ParameterName IS NOT NULL AND @ParameterSerial IS NULL)

    GOTO labelOK

    IF (@ParameterId = 0 AND @ParameterName IS NULL AND @ParameterSerial IS NOT NULL)

    GOTO labelOK

    IF (@ParameterId = 0 AND @ParameterName IS NULL AND @ParameterSerial IS NULL)

    GOTO labelOK

    BEGIN

    SET @MessageAlias = N'TOU56061'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORMESSAGESPECIFIED

    END

    /* -------------------------------------------------------------------

    Check the session token is current and a valid account is reading

    the record.

    ------------------------------------------------------------------- */

    labelOK: SET @Return = NULL

    EXECUTE @Return = [dbo].[CheckAccess]

    @AccountId = @AccountId OUTPUT,

    @Active = @ParameterActive OUTPUT,

    @AuditAccessAlias = N'GET',

    @AuditCategoryAlias = N'MACHINE',

    @AuditId = @ParameterAuditId,

    @MessageAlias = @MessageAlias OUTPUT,

    @Token = @Token

    SET @Error = @@ERROR

    IF (@Error <> 0 OR @Return IS NULL OR @Return <> 0)

    BEGIN

    SET @MessageAlias = ISNULL(LTRIM(RTRIM(@MessageAlias)),N'TOU59998')

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORMESSAGESPECIFIED

    END

    /* -------------------------------------------------------------------

    Get the resultset.

    ------------------------------------------------------------------- */

    BEGIN

    SET NOCOUNT OFF

    SELECT

    [Description],

    [Id],

    [ModelCategoryId],

    [Name],

    [Serial]

    FROM

    [dbo].[Machine](@ParameterActive)

    WHERE

    CASE @ParameterId WHEN 0 THEN 0 ELSE [Id] END = @ParameterId

    AND CASE ISNULL(@ParameterName,N'') WHEN N'' THEN N'' ELSE [Name] END = ISNULL(@ParameterName,N'')

    AND CASE ISNULL(@ParameterSerial,N'') WHEN N'' THEN N'' ELSE [Serial] END = ISNULL(@ParameterSerial,N'')

    SELECT @Error = @@ERROR, @RowCount = @@ROWCOUNT

    SET NOCOUNT ON

    IF (@Error <> 0)

    BEGIN

    SET @MessageAlias = N'TOU56521'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORMESSAGESPECIFIED

    END

    IF (@RowCount = 0)

    BEGIN

    SET @MessageAlias = N'TOU56063'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,default)

    GOTO labelERRORMESSAGESPECIFIED

    END

    RETURN 0

    END

    /* -------------------------------------------------------------------

    Generic error handling

    ------------------------------------------------------------------- */

    labelERROR: BEGIN

    SET @MessageAlias = N'TOU59999'

    SET @MessageText = [dbo].[AuditMessageFormat](@MessageAlias,@MessageObject,@Location)

    GOTO labelERRORMESSAGESPECIFIED

    END

    labelERRORMESSAGESPECIFIED: BEGIN

    RAISERROR (@MessageText,10,1)

    RETURN CAST(RIGHT(LTRIM(RTRIM(@MessageAlias)),5) AS [int])

    END

    END

    GO

    Peter Edmunds ex-Geek