USP_REVENUE_GETSTOCKSALEGLDISTRIBUTION_CUSTOMUPDATEFROMXML_2

Stored procedure to update stock sale GL distribution records from the given xml collection.

Parameters

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

Definition

Copy


            CREATE procedure dbo.USP_REVENUE_GETSTOCKSALEGLDISTRIBUTION_CUSTOMUPDATEFROMXML_2
            (
                @STOCKSALEID 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,
                [PROJECT] nvarchar(100),
                [REFERENCE] nvarchar(100),
                [TRANSACTIONTYPECODE] tinyint,
                [ORGANIZATIONAMOUNT] money,
                [BASECURRENCYID] uniqueidentifier,
                [TRANSACTIONAMOUNT] money,
                [TRANSACTIONCURRENCYID] uniqueidentifier,
                [BASEEXCHANGERATEID] uniqueidentifier,
                [ORGANIZATIONEXCHANGERATEID] uniqueidentifier
            )

            insert into @TempTbl select 
                [ACCOUNT],
                [AMOUNT],
                [GLPAYMENTMETHODREVENUETYPEMAPPINGID],
                [ID],
                [PROJECT],
                [REFERENCE],
                [TRANSACTIONTYPECODE],
                [ORGANIZATIONAMOUNT],
                [BASECURRENCYID],
                [TRANSACTIONAMOUNT],
                [TRANSACTIONCURRENCYID],
                [BASEEXCHANGERATEID],
                [ORGANIZATIONEXCHANGERATEID]
            from dbo.UFN_REVENUE_GETSTOCKSALEGLDISTRIBUTION_FROMITEMLISTXML(@XML)

            declare @REVENUEID uniqueidentifier;

            select @REVENUEID = T2.REVENUEID from STOCKDETAIL T1 
                join REVENUEPAYMENTMETHOD T2 on T1.ID = T2.ID 
                join STOCKSALE T3 on T1.ID = T3.STOCKDETAILID
            where T3.ID = @STOCKSALEID

            if @REVENUEID is null  
                select top 1 
                    @REVENUEID = STOCKSALEGLDISTRIBUTION.REVENUEID
                from 
                    @TempTbl as [temp]
                inner join
                    dbo.STOCKSALEGLDISTRIBUTION on [temp].ID = STOCKSALEGLDISTRIBUTION.ID
                inner join 
                    dbo.GLTRANSACTION on STOCKSALEGLDISTRIBUTION.GLTRANSACTIONID = GLTRANSACTION.ID;


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

            if @@Error <> 0
                return 1;

            declare @contextCache varbinary(128);
            declare @e int;

            -- cache current context information 

            set @contextCache = CONTEXT_INFO();

            -- set CONTEXT_INFO to @CHANGEAGENTID 

            if not @CHANGEAGENTID is null
                set CONTEXT_INFO @CHANGEAGENTID;

            -- delete any items that no longer exist in the XML table

            delete from dbo.[STOCKSALEGLDISTRIBUTION] where [STOCKSALEGLDISTRIBUTION].ID in 
                (select ID from dbo.UFN_REVENUE_GETSTOCKSALEGLDISTRIBUTION
                (
                    @STOCKSALEID
                )
                EXCEPT select ID from @TempTbl)    

            select @e=@@error;

            -- reset CONTEXT_INFO to previous value 

            if not @contextCache is null
                set CONTEXT_INFO @contextCache;

            if @e <> 0
                return 2;

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

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

            --Update the corresponding rows in the GLTRANSACTION table

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


            if @@Error <> 0
                return 3;    

            -- insert new items

            declare @DISTRIBUTIONS table(
                GLTRANSACTIONID uniqueidentifier,
                ACCOUNT nvarchar(100),
                AMOUNT money,
                PROJECT nvarchar(100),
                REFERENCE nvarchar(255),
                TRANSACTIONTYPECODE tinyint,
                GLPAYMENTMETHODREVENUETYPEMAPPINGID uniqueidentifier,
                STOCKSALEGLDISTRIBUTIONID uniqueidentifier,
                [ORGANIZATIONAMOUNT] money,
                [BASECURRENCYID] uniqueidentifier,
                [TRANSACTIONAMOUNT] money,
                [TRANSACTIONCURRENCYID] uniqueidentifier,
                [BASEEXCHANGERATEID] uniqueidentifier,
                [ORGANIZATIONEXCHANGERATEID] uniqueidentifier
            );

            insert into @DISTRIBUTIONS(GLTRANSACTIONID, ACCOUNT, AMOUNT, PROJECT, REFERENCE, TRANSACTIONTYPECODE, GLPAYMENTMETHODREVENUETYPEMAPPINGID, STOCKSALEGLDISTRIBUTIONID, [ORGANIZATIONAMOUNT], [BASECURRENCYID], [TRANSACTIONAMOUNT], [TRANSACTIONCURRENCYID], [BASEEXCHANGERATEID], [ORGANIZATIONEXCHANGERATEID])
            select 
                newid(), 
                [ACCOUNT],
                [AMOUNT],
                [PROJECT],
                [REFERENCE],
                [TRANSACTIONTYPECODE], 
                [GLPAYMENTMETHODREVENUETYPEMAPPINGID],
                [ID],
                [ORGANIZATIONAMOUNT],
                [BASECURRENCYID],
                [TRANSACTIONAMOUNT],
                [TRANSACTIONCURRENCYID],
                [BASEEXCHANGERATEID],
                [ORGANIZATIONEXCHANGERATEID]
            from @TempTbl as [temp]
            where not exists (select ID from dbo.[STOCKSALEGLDISTRIBUTION] as data where data.ID = [temp].ID)

            -- Insert rows in GLTRANSACTION table

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

            -- Insert rows in STOCKSALEGLDISTRIBUTION table

            insert into dbo.STOCKSALEGLDISTRIBUTION
                (ID, STOCKSALEID, REVENUEID, GLPAYMENTMETHODREVENUETYPEMAPPINGID, PROJECT, REFERENCE, AMOUNT, ACCOUNT, TRANSACTIONTYPECODE, GLTRANSACTIONID, ADDEDBYID, CHANGEDBYID, DATEADDED, DATECHANGED, [ORGANIZATIONAMOUNT], [BASECURRENCYID], [TRANSACTIONAMOUNT], [TRANSACTIONCURRENCYID], [BASEEXCHANGERATEID], [ORGANIZATIONEXCHANGERATEID])
            select
                STOCKSALEGLDISTRIBUTIONID,
                @STOCKSALEID,
                @REVENUEID,
                GLPAYMENTMETHODREVENUETYPEMAPPINGID,
                PROJECT,
                REFERENCE, 
                AMOUNT,
                ACCOUNT,
                TRANSACTIONTYPECODE,
                GLTRANSACTIONID,
                @CHANGEAGENTID,
                @CHANGEAGENTID,
                @CHANGEDATE,
                @CHANGEDATE,
                [ORGANIZATIONAMOUNT],
                [BASECURRENCYID],
                [TRANSACTIONAMOUNT],
                [TRANSACTIONCURRENCYID],
                [BASEEXCHANGERATEID],
                [ORGANIZATIONEXCHANGERATEID]
            from 
                @DISTRIBUTIONS;

            if @@Error <> 0
                return 4;

            return 0;