USP_KPI_MARKETING_MAILING_ROIPERCENT_INTERNAL

Internal SP used to calculate a value for the Marketing Effort Return on Investment (ROI) Percent KPI.

Parameters

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

Definition

Copy


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

  declare @DATEREFRESHED datetime;
  declare @MAILINGID uniqueidentifier;
  declare @TOTALCOST money;
  declare @TOTALGIFTAMOUNT money;

  declare @RESPONSECOUNTS table
  (
    [OFFERS] int
    [RESPONDERS] int
    [RESPONSES] int
    [TOTALGIFTAMOUNT] money, 
    [RESPONSERATE] decimal(19,4), 
    [ORGANIZATIONTOTALGIFTAMOUNT] money,
    [FIRSTRESPONSEDATE] datetime
  );

  set @TOTALGIFTAMOUNT = 0;
  set @TOTALCOST = 0;

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

  open MAILINGSCURSOR;
  fetch next from MAILINGSCURSOR into @MAILINGID, @DATEREFRESHED;

  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 >= @DATEREFRESHED
      select
        @TOTALGIFTAMOUNT = @TOTALGIFTAMOUNT + [ORGANIZATIONTOTALGIFTAMOUNT],
        @TOTALCOST = @TOTALCOST + [ORGANIZATIONTOTALCOST]
      from dbo.[MKTSEGMENTATIONACTIVE]
      where [ID] = @MAILINGID;
    else
      begin
        delete from @RESPONSECOUNTS;

        insert into @RESPONSECOUNTS
          exec dbo.[USP_MKTSEGMENTATION_GETRESPONSECOUNTS] @MAILINGID, @ASOFDATE;

        select
          @TOTALGIFTAMOUNT = @TOTALGIFTAMOUNT + [ORGANIZATIONTOTALGIFTAMOUNT]
        from @RESPONSECOUNTS;

        /* Since total cost for the mailing will never change (unless they change the fixed cost on the mailing, but even then */
        /* the cache will be updated when they save the new fixed cost), so just grab the total cost from the mailing cache. */
        select
          @TOTALCOST = @TOTALCOST + [ORGANIZATIONTOTALCOST]
        from dbo.[MKTSEGMENTATIONACTIVE]
        where [ID] = @MAILINGID;
      end

    fetch next from MAILINGSCURSOR into @MAILINGID, @DATEREFRESHED;
  end

  close MAILINGSCURSOR;
  deallocate MAILINGSCURSOR;

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