USP_KPI_MARKETING_SEGMENT_RESPONSERATE_INTERNAL

Internal SP used to calculate a value for the Segment Response Rate KPI.

Parameters

Parameter Parameter Type Mode Description
@ASOFDATE datetime IN
@SEGMENTID uniqueidentifier IN
@VALUE decimal(19, 4) INOUT

Definition

Copy


CREATE procedure dbo.[USP_KPI_MARKETING_SEGMENT_RESPONSERATE_INTERNAL]
(
  @ASOFDATE datetime,
  @SEGMENTID uniqueidentifier = null,
  @VALUE decimal(19,4) = 0 output
)
as
  set nocount on;

  declare @MAILINGSEGMENTID uniqueidentifier;
  declare @MAILINGTESTSEGMENTID uniqueidentifier;
  declare @MAILINGDATEREFRESHED datetime;
  declare @QUANTITY int;
  declare @RESPONSES int;
  declare @RESPONSECOUNTS table([OFFERS] int, [RESPONDERS] int, [RESPONSES] int, [TOTALGIFTAMOUNT] money, [AVERAGEGIFTAMOUNT] money, [ORGANIZATIONTOTALGIFTAMOUNT] money, [ORGANIZATIONAVERAGEGIFTAMOUNT] money);

  set @QUANTITY = 0;
  set @RESPONSES = 0;

  declare SEGMENTCURSOR cursor local fast_forward for
    select
      [MKTSEGMENTATIONSEGMENT].[ID],
      null,
      cast(isnull([MKTSEGMENTATIONREFRESHPROCESS].[DATEREFRESHED], [MKTSEGMENTATION].[ACTIVATEDATE]) as date)
    from dbo.[MKTSEGMENT]
    /*#IDSETEXTENSION*/
    inner join dbo.[MKTSEGMENTATIONSEGMENT] on [MKTSEGMENTATIONSEGMENT].[SEGMENTID] = [MKTSEGMENT].[ID]
    inner join dbo.[MKTSEGMENTATIONREFRESHPROCESS] on [MKTSEGMENTATIONREFRESHPROCESS].[SEGMENTATIONID] = [MKTSEGMENTATIONSEGMENT].[SEGMENTATIONID]
    inner join dbo.[MKTSEGMENTATION] on [MKTSEGMENTATION].[ID] = [MKTSEGMENTATIONSEGMENT].[SEGMENTATIONID]
    where (@SEGMENTID is null or @SEGMENTID = [MKTSEGMENT].[ID])
    union
    select
      [MKTSEGMENTATIONSEGMENT].[ID],
      [MKTSEGMENTATIONTESTSEGMENT].[ID],
      cast(isnull([MKTSEGMENTATIONREFRESHPROCESS].[DATEREFRESHED], [MKTSEGMENTATION].[ACTIVATEDATE]) as date)
    from dbo.[MKTSEGMENT]
    /*#IDSETEXTENSION*/
    inner join dbo.[MKTSEGMENTATIONSEGMENT] on [MKTSEGMENTATIONSEGMENT].[SEGMENTID] = [MKTSEGMENT].[ID]
    inner join dbo.[MKTSEGMENTATIONTESTSEGMENT] on [MKTSEGMENTATIONTESTSEGMENT].[SEGMENTID] = [MKTSEGMENTATIONSEGMENT].[ID]
    inner join dbo.[MKTSEGMENTATIONREFRESHPROCESS] on [MKTSEGMENTATIONREFRESHPROCESS].[SEGMENTATIONID] = [MKTSEGMENTATIONSEGMENT].[SEGMENTATIONID]
    inner join dbo.[MKTSEGMENTATION] on [MKTSEGMENTATION].[ID] = [MKTSEGMENTATIONSEGMENT].[SEGMENTATIONID]
    where (@SEGMENTID is null or @SEGMENTID = [MKTSEGMENT].[ID]);

  open SEGMENTCURSOR;
  fetch next from SEGMENTCURSOR into @MAILINGSEGMENTID, @MAILINGTESTSEGMENTID, @MAILINGDATEREFRESHED;

  while (@@FETCH_STATUS = 0)
  begin
    /* If the "As of date" is the same day or after the date the mailing was last refreshed, then grab */
    /* the value from the mailing cache, otherwise perform the calculation using the "As of date". */
    if @ASOFDATE >= @MAILINGDATEREFRESHED
      select
        @QUANTITY = @QUANTITY + [QUANTITY],
        @RESPONSES = @RESPONSES + [RESPONSES]
      from dbo.[MKTSEGMENTATIONSEGMENTACTIVE]
      where [SEGMENTID] = @MAILINGSEGMENTID
      and ((@MAILINGTESTSEGMENTID is null and [TESTSEGMENTID] is null) or (@MAILINGTESTSEGMENTID is not null and [TESTSEGMENTID] = @MAILINGTESTSEGMENTID));
    else
      begin
        delete from @RESPONSECOUNTS;

        insert into @RESPONSECOUNTS
          exec dbo.[USP_MKTSEGMENTATIONSEGMENT_GETRESPONSECOUNTS] @MAILINGSEGMENTID, @MAILINGTESTSEGMENTID, @ASOFDATE;

        select
          @QUANTITY = @QUANTITY + [OFFERS],
          @RESPONSES = @RESPONSES + [RESPONSES]
        from @RESPONSECOUNTS;
      end

    fetch next from SEGMENTCURSOR into @MAILINGSEGMENTID, @MAILINGTESTSEGMENTID, @MAILINGDATEREFRESHED;
  end

  close SEGMENTCURSOR;
  deallocate SEGMENTCURSOR;

  set @VALUE = cast((case when @QUANTITY > 0 then cast(@RESPONSES as decimal(19,4)) / cast(@QUANTITY as decimal(19,4)) else 0 end) as decimal(19,4));