USP_DATAFORMTEMPLATE_EDIT_MKTSEGMENTATIONSEGMENT_2

The save procedure used by the edit dataform template "Marketing Effort Segment Edit Form 2".

Parameters

Parameter Parameter Type Mode Description
@ID uniqueidentifier IN The input ID parameter indicating the ID of the record being edited.
@CHANGEAGENTID uniqueidentifier IN Input parameter indicating the ID of the change agent invoking the procedure.
@SEGMENTID uniqueidentifier IN Segment
@CODE nvarchar(10) IN Code
@PACKAGEID uniqueidentifier IN Package
@PACKAGECODE nvarchar(10) IN Package code
@RESPONSERATE decimal(5, 2) IN Response rate
@GIFTAMOUNT money IN Gift amount
@SAMPLESIZE int IN Sample size
@SAMPLESIZETYPECODE tinyint IN Sample size type
@SAMPLESIZEMETHODCODE tinyint IN Sample size method
@SAMPLESIZEEXCLUDEREMAINDER bit IN Exclude remaining records from the marketing effort
@ASKLADDERID uniqueidentifier IN Ask ladder

Definition

Copy


CREATE procedure dbo.USP_DATAFORMTEMPLATE_EDIT_MKTSEGMENTATIONSEGMENT_2
(
  @ID uniqueidentifier,
  @CHANGEAGENTID uniqueidentifier = null,
  @SEGMENTID uniqueidentifier,
  @CODE nvarchar(10),
  @PACKAGEID uniqueidentifier,
  @PACKAGECODE nvarchar(10),
  @RESPONSERATE decimal(5,2),
  @GIFTAMOUNT money,
  @SAMPLESIZE int,
  @SAMPLESIZETYPECODE tinyint,
  @SAMPLESIZEMETHODCODE tinyint,
  @SAMPLESIZEEXCLUDEREMAINDER bit,
  @ASKLADDERID uniqueidentifier
)
as
  set nocount on;

  declare @SEGMENTATIONID uniqueidentifier;
  declare @ACTIVE bit;
  declare @SEGMENTTYPECODE tinyint;
  declare @ISVENDORMANAGED bit;
  declare @SEGMENTATIONSOURCECODEID uniqueidentifier;
  declare @MAILINGTYPECODE tinyint;
  declare @PACKAGECHANNELCODE tinyint;
  declare @OLDSEGMENTID uniqueidentifier;
  declare @OLDCODE nvarchar(10);
  declare @OLDSEGMENTATIONPACKAGEID uniqueidentifier;
  declare @OLDPACKAGEID uniqueidentifier;
  declare @OLDPACKAGECHANNELCODE tinyint;
  declare @OLDSAMPLESIZE int;
  declare @OLDSAMPLESIZETYPECODE tinyint;
  declare @OLDSAMPLESIZEMETHODCODE tinyint;
  declare @OLDSAMPLESIZEEXCLUDEREMAINDER bit;
  declare @CURRENTDATE datetime;
  declare @USEADDRESSPROCESSING bit;
  declare @ADDRESSPROCESSINGOPTIONID uniqueidentifier;

  begin try
    select
      @SEGMENTATIONID = [MKTSEGMENTATION].[ID],
      @SEGMENTATIONSOURCECODEID = [MKTSEGMENTATION].[SOURCECODEID],
      @ACTIVE = [MKTSEGMENTATION].[ACTIVE],
      @SEGMENTTYPECODE = [MKTSEGMENT].[SEGMENTTYPECODE],
      @ISVENDORMANAGED = (case when [MKTSEGMENT].[SEGMENTTYPECODE] = 2 then dbo.[UFN_MKTSEGMENT_ISVENDORMANAGEDLIST]([MKTSEGMENT].[ID]) else 0 end),
      @MAILINGTYPECODE = [MKTSEGMENTATION].[MAILINGTYPECODE],
      @USEADDRESSPROCESSING = [MKTSEGMENTATION].[USEADDRESSPROCESSING],
      @ADDRESSPROCESSINGOPTIONID = [MKTSEGMENTATION].[ADDRESSPROCESSINGOPTIONID]
    from dbo.[MKTSEGMENTATIONSEGMENT]
    inner join dbo.[MKTSEGMENT] on [MKTSEGMENT].[ID] = [MKTSEGMENTATIONSEGMENT].[SEGMENTID]
    inner join dbo.[MKTSEGMENTATION] on [MKTSEGMENTATION].[ID] = [MKTSEGMENTATIONSEGMENT].[SEGMENTATIONID]
    where [MKTSEGMENTATIONSEGMENT].[ID] = @ID;

    if @ACTIVE = 0
      begin
        --Check if the mailing is currently being activated...

        exec dbo.[USP_MKTSEGMENTATION_CHECKACTIVATION] @SEGMENTATIONID;

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

        set @CURRENTDATE = GetDate();

        select @PACKAGECHANNELCODE = [CHANNELCODE] from dbo.[MKTPACKAGE] where [ID] = @PACKAGEID;

        /* Grab the old packageID info before we save the segment */
        select 
          @OLDSEGMENTID = [SEG].[SEGMENTID],
          @OLDSEGMENTATIONPACKAGEID = (select [PAK].[ID] from dbo.[MKTSEGMENTATIONPACKAGE] as [PAK] where [PAK].[SEGMENTATIONID] = [SEG].[SEGMENTATIONID] and [PAK].[PACKAGEID] = [SEG].[PACKAGEID]),
          @OLDPACKAGEID = [SEG].[PACKAGEID],
          @OLDPACKAGECHANNELCODE = [MKTPACKAGE].[CHANNELCODE],
          @OLDSAMPLESIZE = [SEG].[SAMPLESIZE],
          @OLDSAMPLESIZETYPECODE = [SEG].[SAMPLESIZETYPECODE],
          @OLDSAMPLESIZEMETHODCODE = [SEG].[SAMPLESIZEMETHODCODE],
          @OLDSAMPLESIZEEXCLUDEREMAINDER = [SEG].[SAMPLESIZEEXCLUDEREMAINDER]
        from dbo.[MKTSEGMENTATIONSEGMENT] as [SEG]
        inner join dbo.[MKTPACKAGE] on [MKTPACKAGE].[ID] = [SEG].[PACKAGEID]
        where [SEG].[ID] = @ID;

        if @SAMPLESIZETYPECODE = 0 and @SAMPLESIZE = 100
          set @SAMPLESIZEEXCLUDEREMAINDER = 1;

        --For acknowledgement mailings, don't allow the user to change the segment or package...

        if @MAILINGTYPECODE = 1 and (@SEGMENTID <> @OLDSEGMENTID or @PACKAGEID <> @OLDPACKAGEID)
          begin
            set @SEGMENTID = @OLDSEGMENTID;
            set @PACKAGEID = @OLDPACKAGEID;
          end

        /* Save the segment */
        update dbo.[MKTSEGMENTATIONSEGMENT] set 
          [SEGMENTID] = @SEGMENTID,
          [CODE] = @CODE,
          [PACKAGEID] = @PACKAGEID,
          [RESPONSERATE] = @RESPONSERATE,
          [GIFTAMOUNT] = @GIFTAMOUNT,
          [SAMPLESIZE] = @SAMPLESIZE,
          [SAMPLESIZETYPECODE] = @SAMPLESIZETYPECODE,
          [SAMPLESIZEMETHODCODE] = @SAMPLESIZEMETHODCODE,
          [SAMPLESIZEEXCLUDEREMAINDER] = @SAMPLESIZEEXCLUDEREMAINDER,
          [ASKLADDERID] = @ASKLADDERID,
          [CHANGEDBYID] = @CHANGEAGENTID,
          [DATECHANGED] = @CURRENTDATE
        where [ID] = @ID;

        /* Save and update the package for the segment */
        if @OLDPACKAGEID <> @PACKAGEID
          begin
            /* Remove the old package, only if is not being used by any other segments and test segments */
            if not exists(select [ID] from dbo.[MKTSEGMENTATIONSEGMENT] where [SEGMENTATIONID] = @SEGMENTATIONID and [PACKAGEID] = @OLDPACKAGEID) and
               not exists(select [MKTSEGMENTATIONTESTSEGMENT].[ID] from dbo.[MKTSEGMENTATIONTESTSEGMENT] inner join dbo.[MKTSEGMENTATIONSEGMENT] on [MKTSEGMENTATIONSEGMENT].[ID] = [MKTSEGMENTATIONTESTSEGMENT].[SEGMENTID] where [MKTSEGMENTATIONSEGMENT].[SEGMENTATIONID] = @SEGMENTATIONID and [MKTSEGMENTATIONTESTSEGMENT].[PACKAGEID] = @OLDPACKAGEID)
              exec dbo.[USP_MKTSEGMENTATIONPACKAGE_DELETE] @OLDSEGMENTATIONPACKAGEID, @CHANGEAGENTID;

            /* Add the new package, only if it doesn't exist already */
            if not exists(select [ID] from dbo.[MKTSEGMENTATIONPACKAGE] where [SEGMENTATIONID] = @SEGMENTATIONID and [PACKAGEID] = @PACKAGEID)
              exec dbo.[USP_DATAFORMTEMPLATE_ADD_MKTSEGMENTATIONPACKAGE] null, @CHANGEAGENTID, @SEGMENTATIONID, @PACKAGEID;
          end

        /* Update the package with the selected code */
        select
          @OLDCODE = coalesce([CODE], '')
        from dbo.[MKTPACKAGE]
        where [ID] = @PACKAGEID;

        if @OLDCODE <> @PACKAGECODE
          update dbo.[MKTPACKAGE] set
            [CODE] = @PACKAGECODE,
            [CHANGEDBYID] = @CHANGEAGENTID,
            [DATECHANGED] = @CURRENTDATE
          where [ID] = @PACKAGEID;

        /* Update the segment with the selected code */
        select
          @OLDCODE = coalesce([CODE], '')
        from dbo.[MKTSEGMENT]
        where [ID] = @SEGMENTID;

        if @OLDCODE <> @CODE and (@SEGMENTTYPECODE <> 2 or (@SEGMENTTYPECODE = 2 and @ISVENDORMANAGED = 0) or (@SEGMENTTYPECODE = 2 and @ISVENDORMANAGED = 1 and @SEGMENTATIONSOURCECODEID is not null))
          exec dbo.[USP_MKTSEGMENT_UPDATECODE] @SEGMENTID, @CODE, @CHANGEAGENTID;

        /* clear the segment cache if the segment or sample size settings changed, or if address processing is being used
           and the new package has a different channel than the old one, since the package's channel can affect record counts 
           when address processing is used */
        if (@OLDSEGMENTID <> @SEGMENTID or @OLDSAMPLESIZEEXCLUDEREMAINDER <> @SAMPLESIZEEXCLUDEREMAINDER or (@SAMPLESIZEEXCLUDEREMAINDER = 0 and (@OLDSAMPLESIZE <> @SAMPLESIZE or @OLDSAMPLESIZETYPECODE <> @SAMPLESIZETYPECODE or @OLDSAMPLESIZEMETHODCODE <> @SAMPLESIZEMETHODCODE))) or 
           (@OLDPACKAGECHANNELCODE <> @PACKAGECHANNELCODE and @USEADDRESSPROCESSING = 1 and @ADDRESSPROCESSINGOPTIONID is not null
          /* Clear the cache for this segment and all segments after it with the same record type */
          exec dbo.[USP_MKTSEGMENTATIONSEGMENT_CLEARCACHE] @ID, 1, 1;
      end
  end try

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

  return 0;