USP_RECORDOPERATION_MEMBERSHIPLEVELDECREASESEQUENCE

Executes the "Membership Level: Decrease Sequence" record operation.

Parameters

Parameter Parameter Type Mode Description
@ID uniqueidentifier IN Input parameter indicating the ID of the record being updated.
@CHANGEAGENTID uniqueidentifier IN Input parameter indicating the ID of the change agent invoking the update.

Definition

Copy


                    CREATE procedure dbo.USP_RECORDOPERATION_MEMBERSHIPLEVELDECREASESEQUENCE
                    (
                        @ID uniqueidentifier,
                        @CHANGEAGENTID uniqueidentifier
                    )
                    as
                    begin
                        set nocount on;

                        if @CHANGEAGENTID is null
                            exec dbo.USP_CHANGEAGENT_GETORCREATECHANGEAGENT @CHANGEAGENTID output;

                        declare @CURRENTDATE datetime = getdate();
                        declare @CURRENTSEQUENCE int = 0;
                        declare @NEWSEQUENCE int = 0;
                        declare @MINSEQUENCE int = 0;
                        declare @MEMBERSHIPPROGRAMID uniqueidentifier;
                        declare @ISACTIVE bit;

                        select
                            @MEMBERSHIPPROGRAMID = MEMBERSHIPPROGRAMID,
                            @ISACTIVE = ISACTIVE
                        from
                            dbo.MEMBERSHIPLEVEL
                        where
                            ID = @ID;

                        -- Use identity column to try and resequence the membership levels in case invalid or duplicate sequences were inserted

                        declare @TEMPMEMBERSHIPLEVELS table (
                            ID uniqueidentifier,
                            ISACTIVE bit,
                            CURRENTSEQUENCE int identity(0,1),
                            NEWSEQUENCE int
                        );

                        insert into @TEMPMEMBERSHIPLEVELS (ID, ISACTIVE)
                            select ID, ISACTIVE
                            from dbo.MEMBERSHIPLEVEL
                            where MEMBERSHIPPROGRAMID = @MEMBERSHIPPROGRAMID
                            order by SEQUENCE;

                        update @TEMPMEMBERSHIPLEVELS set NEWSEQUENCE = CURRENTSEQUENCE;

                        select @CURRENTSEQUENCE = CURRENTSEQUENCE from @TEMPMEMBERSHIPLEVELS where ID = @ID;
                        select @MINSEQUENCE = min(CURRENTSEQUENCE) from @TEMPMEMBERSHIPLEVELS where @ISACTIVE = 0 or ISACTIVE = 1;

                        if @CURRENTSEQUENCE > 0
                        begin
                            -- This means that the level is the lowest active sequence and needs to be placed first

                            if @CURRENTSEQUENCE = @MINSEQUENCE
                                set @NEWSEQUENCE = 0;
                            else
                                select @NEWSEQUENCE = max(CURRENTSEQUENCE)
                                from @TEMPMEMBERSHIPLEVELS
                                where CURRENTSEQUENCE < @CURRENTSEQUENCE and (@ISACTIVE = 0 or ISACTIVE = 1);

                            update @TEMPMEMBERSHIPLEVELS
                            set NEWSEQUENCE = NEWSEQUENCE + 1
                            where CURRENTSEQUENCE < @CURRENTSEQUENCE and CURRENTSEQUENCE >= @NEWSEQUENCE;

                            update @TEMPMEMBERSHIPLEVELS
                            set NEWSEQUENCE = @NEWSEQUENCE
                            where ID = @ID;
                        end

                        begin try
                            update
                                dbo.MEMBERSHIPLEVEL
                            set
                                MEMBERSHIPLEVEL.SEQUENCE = TEMPMEMBERSHIPLEVELS.NEWSEQUENCE,
                                MEMBERSHIPLEVEL.CHANGEDBYID = @CHANGEAGENTID,
                                MEMBERSHIPLEVEL.DATECHANGED = @CURRENTDATE
                            from
                                dbo.MEMBERSHIPLEVEL
                            inner join
                                @TEMPMEMBERSHIPLEVELS as TEMPMEMBERSHIPLEVELS on TEMPMEMBERSHIPLEVELS.ID = MEMBERSHIPLEVEL.ID
                            where
                                MEMBERSHIPLEVEL.SEQUENCE <> TEMPMEMBERSHIPLEVELS.NEWSEQUENCE;
                        end try

                        begin catch
                            exec dbo.USP_RAISE_ERROR;
                            return 1;
                        end catch

                        return 0;
                    end