USP_DATALIST_MKTSEGMENTATIONACTIVATEPROCESS

A datalist of marketing efforts that are ready to be activated.

Parameters

Parameter Parameter Type Mode Description
@CURRENTAPPUSERID uniqueidentifier IN Input parameter indicating the ID of the current user.
@ACTIVESTATUS bit IN Status
@MAILDATEFROM datetime IN Date from
@MAILDATETO datetime IN To
@SHOWUNSCHEDULED bit IN Include marketing efforts with no date
@SITEFILTERMODE tinyint IN Sites
@SITESSELECTED xml IN Sites selected
@SECURITYFEATUREID uniqueidentifier IN Input parameter indicating the ID of the feature to use for site security checking.
@SECURITYFEATURETYPE tinyint IN Input parameter indicating the type of the feature to use for site security checking.

Definition

Copy


CREATE procedure dbo.[USP_DATALIST_MKTSEGMENTATIONACTIVATEPROCESS]
(
  @CURRENTAPPUSERID uniqueidentifier,
  @ACTIVESTATUS bit = 0,
  @MAILDATEFROM datetime = null,
  @MAILDATETO datetime = null,
  @SHOWUNSCHEDULED bit = 1,
  @SITEFILTERMODE tinyint = 0,
  @SITESSELECTED xml = null,
  @SECURITYFEATUREID uniqueidentifier = null,
  @SECURITYFEATURETYPE tinyint = null  
)
as
  set nocount on

  if @SHOWUNSCHEDULED is null set @SHOWUNSCHEDULED = 1;

  select
    [MKTSEGMENTATIONACTIVATEPROCESS].[ID],
    [MKTSEGMENTATIONACTIVATEPROCESS].[SEGMENTATIONID],
    [MKTSEGMENTATION].[CODE],
    [MKTSEGMENTATION].[NAME],
    dbo.[UFN_MKTMARKETINGPLANITEM_PATH]([MKTMARKETINGPLANITEM].[ID], 1) as [PATH],
    [MKTSEGMENTATION].[MAILDATE],
    [MKTSEGMENTATION].[ACTIVE],
    cast((case when exists(select top 1 1 from dbo.[MKTSEGMENTATIONACTIVATE] where [SEGMENTATIONID] = [MKTSEGMENTATION].[ID]) then 1 else 0 end) as bit) as [CRITERIADEFINED],
    [MKTSEGMENTATION].[DESCRIPTION],
    dbo.[UFN_TRANSLATIONFUNCTION_SITE_GETNAME]([MKTSEGMENTATION].[SITEID]) as [SITE],
    [MKTSEGMENTATION].[MAILINGFAMILYTYPECODE],
    [MKTSEGMENTATION].[MAILINGFAMILYTYPE],
    convert(nvarchar(36), [MKTSEGMENTATION].[ID]) + '|' + convert(nvarchar(1), [MKTSEGMENTATION].[MAILINGTYPECODE]) as [GOTOMAILINGCONTEXTID]
  from dbo.[MKTSEGMENTATIONACTIVATEPROCESS]
  inner join dbo.[MKTSEGMENTATION] on [MKTSEGMENTATION].[ID] = [MKTSEGMENTATIONACTIVATEPROCESS].[SEGMENTATIONID]
  left outer join dbo.[MKTMARKETINGPLANITEM] on [MKTSEGMENTATION].[MARKETINGPLANITEMID] = [MKTMARKETINGPLANITEM].[ID]
  where (@ACTIVESTATUS is null or [MKTSEGMENTATION].[ACTIVE] = @ACTIVESTATUS)
  and (@MAILDATEFROM is null or ([MKTSEGMENTATION].[MAILDATE] is not null and [MKTSEGMENTATION].[MAILDATE] >= @MAILDATEFROM) or (@SHOWUNSCHEDULED = 1 and [MKTSEGMENTATION].[MAILDATE] is null))
  and (@MAILDATETO is null or ([MKTSEGMENTATION].[MAILDATE] is not null and [MKTSEGMENTATION].[MAILDATE] <= @MAILDATETO) or (@SHOWUNSCHEDULED = 1 and [MKTSEGMENTATION].[MAILDATE] is null))
  and ((@SHOWUNSCHEDULED = 1) or (@SHOWUNSCHEDULED = 0 and [MKTSEGMENTATION].[MAILDATE] is not null))          
  and (select count(1) from dbo.[MKTSEGMENTATIONSEGMENT] where [SEGMENTATIONID] = [MKTSEGMENTATION].[ID]) > 0
  and [MKTSEGMENTATION].[MAILINGTYPECODE] in (0, 4) -- constituent / public media mailings only

  and [MKTSEGMENTATION].[COMMUNICATIONTYPECODE] = 0 -- no BBEC appeal mailings

  and (dbo.UFN_APPUSER_ISSYSADMIN(@CURRENTAPPUSERID) = 1 or exists (select 1 from dbo.UFN_SITESFORUSERONFEATURE(@CURRENTAPPUSERID,@SECURITYFEATUREID,@SECURITYFEATURETYPE) where SITEID=[MKTSEGMENTATION].[SITEID] or (SITEID is null and [MKTSEGMENTATION].[SITEID] is null)))
  and (@SITEFILTERMODE = 0 or [MKTSEGMENTATION].[SITEID] in (select [SITEID] from dbo.[UFN_SITE_BUILDDATALISTSITEFILTER](@CURRENTAPPUSERID, @SITEFILTERMODE, @SITESSELECTED)))
  order by [MKTSEGMENTATION].[NAME];

  return 0;