USP_REVENUE_GETGIFTFEEPOSTEDGLDISTRIBUTION_CUSTOMUPDATEFROMXML

Stored procedure to update posted gift fees GL distribution records from the given xml collection.

Parameters

Parameter Parameter Type Mode Description
@REVENUEID uniqueidentifier IN
@XML xml IN
@POSTDATE datetime IN
@CHANGEAGENTID uniqueidentifier IN
@CHANGEDATE datetime IN

Definition

Copy


            CREATE procedure dbo.USP_REVENUE_GETGIFTFEEPOSTEDGLDISTRIBUTION_CUSTOMUPDATEFROMXML
            (
                @REVENUEID uniqueidentifier,
                @XML xml,
                @POSTDATE datetime,
                @CHANGEAGENTID uniqueidentifier = null,
                @CHANGEDATE datetime = null
            )

            as

            set nocount on;

            if @CHANGEAGENTID is null
                exec USP_CHANGEAGENT_GETORCREATECHANGEAGENT @CHANGEAGENTID output

            if @CHANGEDATE is null 
                set @CHANGEDATE = getdate()

            -- build a temporary table containing the values from the XML

            declare @TempTbl table (
               [ACCOUNT] nvarchar(100),
               [AMOUNT] money,
               [GLPAYMENTMETHODREVENUETYPEMAPPINGID] uniqueidentifier,
               [ID] uniqueidentifier,
               [REFERENCE] nvarchar(255),
               [TRANSACTIONTYPECODE] tinyint)

            insert into @TempTbl select 
                [ACCOUNT],
                [AMOUNT],
                [GLPAYMENTMETHODREVENUETYPEMAPPINGID],
                [ID],
                [REFERENCE],
                [TRANSACTIONTYPECODE] 
            from dbo.UFN_REVENUE_GETGIFTFEEGLDISTRIBUTION_FROMITEMLISTXML(@XML)

            update @TempTbl set ID = newid() where (ID is null) or (ID = '00000000-0000-0000-0000-000000000000');

            if @@Error <> 0
                return 1;

            -- update the items that exist in the XML table and the db

            merge into  dbo.[GIFTFEEGLDISTRIBUTION]
            using  @TempTbl as [temp] on [GIFTFEEGLDISTRIBUTION].ID = [temp].ID
            when matched 
                and (
                    ([GIFTFEEGLDISTRIBUTION].[ACCOUNT]<>temp.[ACCOUNT]) or 
                    ([GIFTFEEGLDISTRIBUTION].[ACCOUNT] is null and temp.[ACCOUNT] is not null) or 
                    ([GIFTFEEGLDISTRIBUTION].[ACCOUNT] is not null and temp.[ACCOUNT] is null) or 
                    ([GIFTFEEGLDISTRIBUTION].[AMOUNT]<>temp.[AMOUNT]) or 
                    ([GIFTFEEGLDISTRIBUTION].[AMOUNT] is null and temp.[AMOUNT] is not null) or 
                    ([GIFTFEEGLDISTRIBUTION].[AMOUNT] is not null and temp.[AMOUNT] is null) or 
                    ([GIFTFEEGLDISTRIBUTION].[GLPAYMENTMETHODREVENUETYPEMAPPINGID]<>temp.[GLPAYMENTMETHODREVENUETYPEMAPPINGID]) or 
                    ([GIFTFEEGLDISTRIBUTION].[GLPAYMENTMETHODREVENUETYPEMAPPINGID] is null and temp.[GLPAYMENTMETHODREVENUETYPEMAPPINGID] is not null) or 
                    ([GIFTFEEGLDISTRIBUTION].[GLPAYMENTMETHODREVENUETYPEMAPPINGID] is not null and temp.[GLPAYMENTMETHODREVENUETYPEMAPPINGID] is null) or 
                    ([GIFTFEEGLDISTRIBUTION].[ID]<>temp.[ID]) or 
                    ([GIFTFEEGLDISTRIBUTION].[ID] is null and temp.[ID] is not null) or 
                    ([GIFTFEEGLDISTRIBUTION].[ID] is not null and temp.[ID] is null) or 
                    ([GIFTFEEGLDISTRIBUTION].[REFERENCE]<>temp.[REFERENCE]) or 
                    ([GIFTFEEGLDISTRIBUTION].[REFERENCE] is null and temp.[REFERENCE] is not null) or 
                    ([GIFTFEEGLDISTRIBUTION].[REFERENCE] is not null and temp.[REFERENCE] is null) or 
                    ([GIFTFEEGLDISTRIBUTION].[TRANSACTIONTYPECODE]<>temp.[TRANSACTIONTYPECODE]) or 
                    ([GIFTFEEGLDISTRIBUTION].[TRANSACTIONTYPECODE] is null and temp.[TRANSACTIONTYPECODE] is not null) or 
                    ([GIFTFEEGLDISTRIBUTION].[TRANSACTIONTYPECODE] is not null and temp.[TRANSACTIONTYPECODE] is null)
                    )                    
            then update 
                    set 
                    [GIFTFEEGLDISTRIBUTION].[ACCOUNT]=temp.[ACCOUNT],
                    [GIFTFEEGLDISTRIBUTION].[AMOUNT]=temp.[AMOUNT],
                    [GIFTFEEGLDISTRIBUTION].[GLPAYMENTMETHODREVENUETYPEMAPPINGID]=temp.[GLPAYMENTMETHODREVENUETYPEMAPPINGID],
                    [GIFTFEEGLDISTRIBUTION].[ID]=temp.[ID],
                    [GIFTFEEGLDISTRIBUTION].[REFERENCE]=temp.[REFERENCE],
                    [GIFTFEEGLDISTRIBUTION].[TRANSACTIONTYPECODE]=temp.[TRANSACTIONTYPECODE],
                    [GIFTFEEGLDISTRIBUTION].CHANGEDBYID = @CHANGEAGENTID,
                    [GIFTFEEGLDISTRIBUTION].DATECHANGED = @CHANGEDATE;



            --Update the corresponding rows in the GLTRANSACTION table

            merge into  dbo.[GLTRANSACTION]
            using  @TempTbl as [temp] 
                inner join dbo.GIFTFEEGLDISTRIBUTION on GIFTFEEGLDISTRIBUTION.ID = [temp].ID
                on [GLTRANSACTION].ID = [temp].ID
            when matched 
            then update
                set 
                    GLTRANSACTION.ACCOUNT = GIFTFEEGLDISTRIBUTION.ACCOUNT,
                    GLTRANSACTION.AMOUNT = GIFTFEEGLDISTRIBUTION.AMOUNT,
                    GLTRANSACTION.REFERENCE = GIFTFEEGLDISTRIBUTION.REFERENCE,
                    GLTRANSACTION.TRANSACTIONTYPECODE = GIFTFEEGLDISTRIBUTION.TRANSACTIONTYPECODE,
                    GLTRANSACTION.POSTDATE = @POSTDATE,
                    GLTRANSACTION.CHANGEDBYID = @CHANGEAGENTID,
                    GLTRANSACTION.DATECHANGED = @CHANGEDATE,
                    GLTRANSACTION.GLACCOUNTID =  dbo.UFN_GLACCOUNT_GETIDFROMACCOUNTANDREVENUE(GIFTFEEGLDISTRIBUTION.ACCOUNT,@REVENUEID);

            if @@Error <> 0
                return 3;    

            -- insert new items

            declare @DISTRIBUTIONS table(
                    GLTRANSACTIONID uniqueidentifier,
                    ACCOUNT nvarchar(100),
                    AMOUNT money,
                    REFERENCE nvarchar(255),
                    TRANSACTIONTYPECODE tinyint,
                    GLPAYMENTMETHODREVENUETYPEMAPPINGID uniqueidentifier,
                    REVENUEGLDISTRIBUTIONID uniqueidentifier
            );

            insert into @DISTRIBUTIONS(GLTRANSACTIONID, ACCOUNT, AMOUNT, REFERENCE, TRANSACTIONTYPECODE, GLPAYMENTMETHODREVENUETYPEMAPPINGID, REVENUEGLDISTRIBUTIONID)
            select 
                newid(), 
                [ACCOUNT],
                [AMOUNT],
                [REFERENCE],
                [TRANSACTIONTYPECODE], 
                [GLPAYMENTMETHODREVENUETYPEMAPPINGID],
                [ID]
            from @TempTbl as [temp]
            where not exists (select ID from dbo.[GIFTFEEGLDISTRIBUTION] as data where data.ID = [temp].ID)

            -- Insert rows in GLTRANSACTION table

            insert into dbo.GLTRANSACTION(ID, TRANSACTIONTYPECODE, ACCOUNT, AMOUNT, REFERENCE, POSTDATE, JOURNAL, ADDEDBYID, CHANGEDBYID, DATEADDED, DATECHANGED, GLACCOUNTID)
            select
                GLTRANSACTIONID,
                TRANSACTIONTYPECODE,
                ACCOUNT,
                AMOUNT,
                REFERENCE,
                @POSTDATE,
                'Blackbaud Enterprise',
                @CHANGEAGENTID,
                @CHANGEAGENTID,
                @CHANGEDATE,
                @CHANGEDATE,
                dbo.UFN_GLACCOUNT_GETIDFROMACCOUNTANDREVENUE([ACCOUNT],@REVENUEID)                    
            from 
                @DISTRIBUTIONS;



            insert into dbo.GIFTFEEGLDISTRIBUTION
                (ID, REVENUEID, GLPAYMENTMETHODREVENUETYPEMAPPINGID, REFERENCE, AMOUNT, ACCOUNT, TRANSACTIONTYPECODE, GLTRANSACTIONID, ADDEDBYID, CHANGEDBYID, DATEADDED, DATECHANGED)
            select
                REVENUEGLDISTRIBUTIONID,
                @REVENUEID,
                GLPAYMENTMETHODREVENUETYPEMAPPINGID,
                REFERENCE, 
                AMOUNT,
                ACCOUNT,
                TRANSACTIONTYPECODE,
                GLTRANSACTIONID,
                @CHANGEAGENTID,
                @CHANGEAGENTID,
                @CHANGEDATE,
                @CHANGEDATE
            from 
                @DISTRIBUTIONS;    

            if @@Error <> 0
                return 4;

            return 0;