declare @runDate datetime = GETDATE(); declare @beginofDay datetime = convert(datetime, convert(varchar(10), DATEADD(day, -14, @runDate), 101)) declare @endOfDay datetime = convert(datetime, convert(varchar(10), DATEADD(day, -13, @runDate), 101)) declare @conversionDate datetime = '{ReleaseDate:yyyy-MM-dd hh:mm:ss}'; SET @conversionDate = DATEADD(day, -14, @conversionDate) declare @contracts table ( Sort int, DAYS_PD varchar(256) null, REMIT_TODESC varchar(256) null, BILLING_NAME varchar(256) null, UATB_AR_ADDRESS_1 varchar(256) null, UATB_AR_ADDRESS_2 varchar(256) null, AR_CITY varchar(256) null, AR_STATE varchar(256) null, AR_ZIP varchar(256) null, UATB_CR_ATTG_NAME varchar(256) null, [CONTRACT] varchar(256) null, TOT_PASTDUE varchar(256) null, COLLECTOR_NAME varchar(256) null, COLLECTOR_EXT varchar(256) null, PRIN_GUAR_NAME_1 varchar(256) null, PRIN_ADD_1 varchar(256) null, PRIN_CITY_1 varchar(256) null, PRIN_ST_1 varchar(256) null, PRIN_ZIP_1 varchar(256) null, PRIN_GAUR_NAME_2 varchar(256) null, PRIN_ADD_2 varchar(256) null, PRIN_CITY_2 varchar(256) null, PRIN_ST_2 varchar(256) null, PRIN_ZIP_2 varchar(256) null, PRIN_GUAR_NAME_3 varchar(256) null, PRIN_ADDR_3 varchar(256) null, PRIN_CITY_3 varchar(256) null, PRIN_ST_3 varchar(256) null, PRIN_ZIP_3 varchar(256) null, PYMTS_MADE varchar(256) null, BLENDED_NET_INVEST varchar(256) null, F_U_CODE varchar(256) null, BRANCH varchar(256) null, OFFICE varchar(256) null, NMF_CONTACT_EMAIL varchar(256) null, AM_ADDL_EMAIL varchar(256) null, ATTENTION varchar(256) null, UATB_CUST_DBA varchar(256) null, PRIN_GUAR_NAME_4 varchar(256) null, PRIN_ADDR_4 varchar(256) null, PRIN_CITY_4 varchar(256) null, PRIN_ST_4 varchar(256) null, PRIN_ZIP_4 varchar(256) null, CustomerName varchar(256) null, CustomerBusinessType varchar(256) null, CustomerAddress1 varchar(256) null, CustomerAddress2 varchar(256) null, CustomerCity varchar(256) null, CustomerState varchar(256) null, CustomerZip varchar(256) null, ApplicationNumber int null, DeclineReason1 varchar(256) null, DeclineReason2 varchar(256) null, DeclineReason3 varchar(256) null, DeclineReason4 varchar(256) null, FICO varchar(256) null, Date_FICO_Pulled varchar(256) null, FICOFactor1 varchar(256) null, FICOFactor2 varchar(256) null, FICOFactor3 varchar(256) null, FICOFactor4 varchar(256) null ) declare @collectorIds table ( Id int ) insert @collectorIds ( Id ) {GenerateCollectorIdSql()} declare @excludedPromos table ( PromoCode varchar(10) ) insert @excludedPromos ( PromoCode ) {GenerateExcludedPromotionsSql()} declare @excludeFollowupCodes table ( Code varchar(3) ) insert @excludeFollowupCodes {GenerateExcludedFollowupCodesSql()} declare @excludedCcans table ( Ccan int ) insert @excludedCcans ( Ccan ) {GenerateExcludedCcansSql()} declare @excludedDealers table ( referenceNumbers varchar(20) ) insert @excludedDealers ( [referenceNumbers] ) {GenerateExlcudeDealersSql()} declare @excludedContracts table ( LessorId int, ContractId int, ScheduleId int ) insert @excludedContracts ( LessorId, ContractId, ScheduleId ) {GenerateExcludedContractsSql()} -- Get the delinquency for the collection letters... insert @contracts ( Sort ,DAYS_PD ,REMIT_TODESC ,BILLING_NAME ,UATB_AR_ADDRESS_1 ,UATB_AR_ADDRESS_2 ,AR_CITY ,AR_STATE ,AR_ZIP ,UATB_CR_ATTG_NAME ,[CONTRACT] ,TOT_PASTDUE ,COLLECTOR_NAME ,COLLECTOR_EXT ,PRIN_GUAR_NAME_1 ,PRIN_ADD_1 ,PRIN_CITY_1 ,PRIN_ST_1 ,PRIN_ZIP_1 ,PRIN_GAUR_NAME_2 ,PRIN_ADD_2 ,PRIN_CITY_2 ,PRIN_ST_2 ,PRIN_ZIP_2 ,PRIN_GUAR_NAME_3 ,PRIN_ADDR_3 ,PRIN_CITY_3 ,PRIN_ST_3 ,PRIN_ZIP_3 ,PYMTS_MADE ,BLENDED_NET_INVEST ,F_U_CODE ,BRANCH ,OFFICE ,NMF_CONTACT_EMAIL ,AM_ADDL_EMAIL ,ATTENTION ,UATB_CUST_DBA ,PRIN_GUAR_NAME_4 ,PRIN_ADDR_4 ,PRIN_CITY_4 ,PRIN_ST_4 ,PRIN_ZIP_4 ,CustomerName ,CustomerBusinessType ,CustomerAddress1 ,CustomerAddress2 ,CustomerCity ,CustomerState ,CustomerZip ,ApplicationNumber ,DeclineReason1 ,DeclineReason2 ,DeclineReason3 ,DeclineReason4 ,FICO ,Date_FICO_Pulled ,FICOFactor1 ,FICOFactor2 ,FICOFactor3 ,FICOFactor4 ) select ccd.DaysPastDue as sort, ccd.DaysPastDue as DAYS_PD, r2.RemitToDesc as REMIT_TODESC, c.ARName as BILLING_NAME, c.ARAddress1 as UATB_AR_ADDRESS_1, c.ARAddress3 as UATB_AR_ADDRESS_2, c.ARCity as AR_CITY, c.ARState as AR_STATE, c.ARZip as AR_ZIP, c.ContactName as UATB_CR_ATTG_NAME, dbo.FormatContractId(c.ContractID, c.ScheduleID, c.LessorID) as [CONTRACT], cm.TotalPastDue as TOT_PASTDUE, p.PersonnelName as COLLECTOR_NAME, p.[PhoneExtension] as COLLECTOR_EXT, '' as PRIN_GUAR_NAME_1, '' as PRIN_ADD_1, '' as PRIN_CITY_1, '' as PRIN_ST_1, '' as PRIN_ZIP_1, '' as PRIN_GAUR_NAME_2, '' as PRIN_ADD_2, '' as PRIN_CITY_2, '' as PRIN_ST_2, '' as PRIN_ZIP_2, '' as PRIN_GUAR_3, '' as PRIN_ADDR_3, '' as PRIN_CITY_3, '' as PRIN_ST_3, '' as PRIN_ZIP_3, cm.PaymentsMade as PYMTS_MADE, cm.BlendedNetInvestment as BLENDED_NET_INVEST, ccm.FollowUpCode as F_U_CODE, b.BranchCode as BRANCH, RIGHT('0000' + CONVERT(varchar(5), p.[PersonnelOfficeID]), 4) as OFFICE, c.ContactEmail as NMF_CONTACT_EMAIL, '' as AM_ADDL_EMAIL, -- Per Shane, do not populate 2019-07-02 c.ARAttention as ATTENTION, cu.DBA as UATB_CUST_DBA, '' as PRIN_GUAR_4, '' as PRIN_ADDR_4, '' as PRIN_CITY_4, '' as PRIN_ST_ZIP, '' as PRIN_ST_ZIP, '' as CustomerName, '' as CustomerBusinessType, '' as CustomerAddress1, '' as CustomerAddress2, '' as CustomerCity, '' as CustomerState, '' as CustomerZip, null as ApplicationNumber, '' as DeclineReason1, '' as DeclineReason2, '' as DeclineReason3, '' as DeclineReason4, '' as FICO, '' as Date_FICO_Pulled, '' as FICOFactor1, '' as FICOFactor2, '' as FICOFactor3, '' as FICOFactor4 from [Contract] c join ( select distinct am.LessorID, am.ContractID, am.ScheduleID from AssetMetrics am left outer join @excludedContracts e on am.LessorID = e.LessorId and am.ContractID = e.ContractId and am.ScheduleID = e.ScheduleId where am.MetricEndDate is null and am.DispositionDate is null and e.ContractId is null ) as a0 on c.LessorID = a0.LessorID and c.ContractID = a0.ContractID and c.ScheduleID = a0.ScheduleID join ContractMetrics cm on c.LessorID = cm.LessorID and c.ContractID = cm.ContractID and c.ScheduleID = cm.ScheduleID join @collectorIds ids on cm.CollectorID = ids.Id join RemitTo r2 on c.RemitToID = r2.RemitToID join ContractCurrentDue ccd on c.LessorID = ccd.LessorID and c.ContractID = ccd.ContractID and c.ScheduleID = ccd.ScheduleID join Branch b on c.BranchKey = b.BranchKey left outer join Personnel p on cm.CollectorID = p.PersonnelID left outer join Customer cu on c.CustomerKey = cu.CustomerKey left outer join BusinessType bt on cu.BusinessTypeID = bt.BusinessTypeID left outer join Dealer d on c.DealerKey = d.DealerKey left outer join ContractCollectionMetrics ccm on c.ContractID = ccm.ContractID and c.LessorID = ccm.LessorID and c.ScheduleID = ccm.ScheduleID left outer join LeadBank lb on c.LeadBankID = lb.LeadBankID left outer join AppPromotion pr on c.PromotionKey = pr.PromotionKey left outer join @excludedDealers ed on d.DealerReferenceNumber = ed.referenceNumbers left outer join @excludeFollowupCodes efu on ccm.FollowUpCode = efu.Code left outer join @excludedPromos ep on pr.PromotionCode = ep.PromoCode left outer join @excludedContracts ec on c.LessorID = ec.LessorId and c.ContractID = ec.ContractId and c.ScheduleID = ec.ScheduleId where cm.MetricEndDate is null and ccd.DaysPastDue in (11, 31, 45) and c.FactEndDate is null and cm.TotalPastDue > 10 and cm.PaymentsMade >= 3 and lb.CategoryId <> 86 and ed.referenceNumbers is null and efu.Code is null and ep.PromoCode is null and ec.ContractId is null and ccm.MetricEndDate is null and cm.EquipmentCost < {MaxEquipmentAmount} /************************************************************ Per Shane's documentation, only the collection letters get the principle guarantors populated ************************************************************/ -- Update with the first principle guarantor update c set PRIN_GUAR_NAME_1 = t1.[Name], PRIN_ADD_1 = t1.Address1, PRIN_CITY_1 = t1.City, PRIN_ST_1 = t1.[State], PRIN_ZIP_1 = t1.Zip from @contracts c join ( select AppKey, [Name], Address1, City, [State], Zip from ( select a.AppKey, cu.[Name], cu.Address1, cu.City, cu.[State], cu.Zip, ROW_NUMBER() OVER (PARTITION BY a.AppKey order by a.AppKey, arp.[RelatedPartyKey]) as rowNumber from @contracts c join [Application] a on c.ApplicationNumber = a.AppKey join AppRelatedParty arp on a.AppKey = arp.AppKey join Customer cu on arp.CustomerKey = cu.CustomerKey ) t0 where t0.rowNumber = 1 ) t1 on c.ApplicationNumber = t1.AppKey -- Update with the second principle guarantor update c set PRIN_GAUR_NAME_2 = t1.[Name], PRIN_ADD_2 = t1.Address1, PRIN_CITY_2 = t1.City, PRIN_ST_2 = t1.[State], PRIN_ZIP_2 = t1.Zip from @contracts c join ( select AppKey, [Name], Address1, City, [State], Zip from ( select a.AppKey, cu.[Name], cu.Address1, cu.City, cu.[State], cu.Zip, ROW_NUMBER() OVER (PARTITION BY a.AppKey order by a.AppKey, arp.[RelatedPartyKey]) as rowNumber from @contracts c join [Application] a on c.ApplicationNumber = a.AppKey join AppRelatedParty arp on a.AppKey = arp.AppKey join Customer cu on arp.CustomerKey = cu.CustomerKey ) t0 where t0.rowNumber = 2 ) t1 on c.ApplicationNumber = t1.AppKey -- Update with the third principle guarantor update c set PRIN_GUAR_NAME_3 = t1.[Name], PRIN_ADDR_3 = t1.Address1, PRIN_CITY_3 = t1.City, PRIN_ST_3 = t1.[State], PRIN_ZIP_3 = t1.Zip from @contracts c join ( select AppKey, [Name], Address1, City, [State], Zip from ( select a.AppKey, cu.[Name], cu.Address1, cu.City, cu.[State], cu.Zip, ROW_NUMBER() OVER (PARTITION BY a.AppKey order by a.AppKey, arp.[RelatedPartyKey]) as rowNumber from @contracts c join [Application] a on c.ApplicationNumber = a.AppKey join AppRelatedParty arp on a.AppKey = arp.AppKey join Customer cu on arp.CustomerKey = cu.CustomerKey ) t0 where t0.rowNumber = 3 ) t1 on c.ApplicationNumber = t1.AppKey -- Update with the forth principle guarantor update c set PRIN_GUAR_NAME_4 = t1.[Name], PRIN_ADDR_4 = t1.Address1, PRIN_CITY_4 = t1.City, PRIN_ST_4 = t1.[State], PRIN_ZIP_4 = t1.Zip from @contracts c join ( select AppKey, [Name], Address1, City, [State], Zip from ( select a.AppKey, cu.[Name], cu.Address1, cu.City, cu.[State], cu.Zip, ROW_NUMBER() OVER (PARTITION BY a.AppKey order by a.AppKey, arp.[RelatedPartyKey]) as rowNumber from @contracts c join [Application] a on c.ApplicationNumber = a.AppKey join AppRelatedParty arp on a.AppKey = arp.AppKey join Customer cu on arp.CustomerKey = cu.CustomerKey ) t0 where t0.rowNumber = 3 ) t1 on c.ApplicationNumber = t1.AppKey -- Now insert all the declined contracts.... INSERT @contracts ( Sort ,DAYS_PD ,REMIT_TODESC ,BILLING_NAME ,UATB_AR_ADDRESS_1 ,UATB_AR_ADDRESS_2 ,AR_CITY ,AR_STATE ,AR_ZIP ,UATB_CR_ATTG_NAME ,[CONTRACT] ,TOT_PASTDUE ,COLLECTOR_NAME ,COLLECTOR_EXT ,PRIN_GUAR_NAME_1 ,PRIN_ADD_1 ,PRIN_CITY_1 ,PRIN_ST_1 ,PRIN_ZIP_1 ,PRIN_GAUR_NAME_2 ,PRIN_ADD_2 ,PRIN_CITY_2 ,PRIN_ST_2 ,PRIN_ZIP_2 ,PRIN_GUAR_NAME_3 ,PRIN_ADDR_3 ,PRIN_CITY_3 ,PRIN_ST_3 ,PRIN_ZIP_3 ,PYMTS_MADE ,BLENDED_NET_INVEST ,F_U_CODE ,BRANCH ,OFFICE ,NMF_CONTACT_EMAIL ,AM_ADDL_EMAIL ,ATTENTION ,UATB_CUST_DBA ,PRIN_GUAR_NAME_4 ,PRIN_ADDR_4 ,PRIN_CITY_4 ,PRIN_ST_4 ,PRIN_ZIP_4 ,CustomerName ,CustomerBusinessType ,CustomerAddress1 ,CustomerAddress2 ,CustomerCity ,CustomerState ,CustomerZip ,ApplicationNumber ,DeclineReason1 ,DeclineReason2 ,DeclineReason3 ,DeclineReason4 ,FICO ,Date_FICO_Pulled ,FICOFactor1 ,FICOFactor2 ,FICOFactor3 ,FICOFactor4 ) SELECT 9999999 AS Sort, 0 AS DAYS_PD, '' AS REMIT_TODESC, '' AS BILLING_NAME, '' AS UATB_AR_ADDRESS_1, '' AS UATB_AR_ADDRESS_2, '' AS AR_CITY, '' AS AR_STATE, '' AS AR_ZIP, '' AS UATB_CR_ATTG_NAME, '' AS [CONTRACT], '' AS TOT_PASTDUE, '' AS COLLECTOR_NAME, '' AS COLLECTOR_EXT, '' AS PRIN_GUAR_NAME_1, '' AS PRIN_ADD_1, '' AS PRIN_CITY_1, '' AS PRIN_ST_1, '' AS PRIN_ZIP_1, '' AS PRIN_GAUR_NAME_2, '' AS PRIN_ADD_2, '' AS PRIN_CITY_2, '' AS PRIN_ST_2, '' AS PRIN_ZIP_2, '' AS PRIN_GUAR_3, '' AS PRIN_ADDR_3, '' AS PRIN_CITY_3, '' AS PRIN_ST_3, '' AS PRIN_ZIP_3, '' AS PYMTS_MADE, '' AS BLENDED_NET_INVEST, '' AS F_U_CODE, b.BranchCode AS BRANCH, '' AS OFFICE, '' AS NMF_CONTACT_EMAIL, '' AS AM_ADDL_EMAIL, '' AS ATTENTION, '' AS UATB_CUST_DBA, '' AS PRIN_GUAR_4, '' AS PRIN_ADDR_4, '' AS PRIN_CITY_4, '' AS PRIN_ST_4, '' AS PRIN_ZIP_4, c.[ARName] AS CustomerName, CASE WHEN bt.BusinessTypeID = 8 AND arpc.FICO IS NULL THEN 'Sole Proprietorship no PG' ELSE bt.BusinessTypeDesc END AS CustomerBusinessType, c.ARAddress1 AS CustomerAddress1, c.ARAddress2 AS CustomerAddress2, c.ARCity AS CustomerCity, c.ARState AS CustomerState, c.ARZip AS CustomerZip, a.AppKey AS ApplicationNumber, adr1.DeclineReasonDesc AS DeclineReason1, adr2.DeclineReasonDesc AS DeclineReason2, adr3.DeclineReasonDesc AS DeclineReason3, adr4.DeclineReasonDesc AS DeclineReason4, arpc.FICO AS FICO, arpc.FICODatePulled AS Date_FICO_Pulled, arpc.FICOFactor1, arpc.FICOFactor2, arpc.FICOFactor3, arpc.FICOFactor4 FROM [Application] a JOIN [ApplicationMetrics] am ON a.AppKey = am.AppKey JOIN Customer c ON a.CustomerKey = c.CustomerKey JOIN ( SELECT t0.AppKey, t0.HistoryDate, t0.DecisionCodeKey FROM ( SELECT dch.AppKey, dch.HistoryDate, dch.DecisionCodeKey, ROW_NUMBER ( ) OVER (PARTITION BY AppKey ORDER BY HistoryDate desc) AS rowCnt FROM AppDecisionCodeHistory dch ) t0 WHERE t0.rowCnt = 1 and t0.DecisionCodeKey in (6, 17) ) dch on a.AppKey = dch.AppKey LEFT OUTER JOIN dbo.AppProductLine al on a.ProductLineKey = al.ProductLineKey LEFT OUTER JOIN ( SELECT AppKey, SyndicationKey, SyndicationDate, RecordUpdateDate, AppSyndicationStatusId FROM ( SELECT AppKey, SyndicationKey, SyndicationDate, RecordUpdateDate,AppSyndicationStatusId, ROW_NUMBER ( ) OVER (PARTITION BY AppKey ORDER BY RecordUpdateDate desc) AS rowCnt FROM [AppSyndication] ) t0 WHERE t0.rowCnt = 1 ) as syn on a.AppKey = syn.AppKey LEFT OUTER JOIN AppPromotion ap on a.PromotionKey = ap.PromotionKey LEFT OUTER JOIN BusinessType bt ON c.BusinessTypeID = bt.BusinessTypeID LEFT OUTER JOIN Branch b ON a.BranchKey = b.BranchKey LEFT OUTER JOIN Syndication s ON a.SyndicationID = s.SyndicationID LEFT OUTER JOIN AppDeclineReason adr1 ON a.DeclineReasonKey1 = adr1.DeclineReasonKey LEFT OUTER JOIN AppDeclineReason adr2 ON a.DeclineReasonKey2 = adr1.DeclineReasonKey LEFT OUTER JOIN AppDeclineReason adr3 ON a.DeclineReasonKey3 = adr1.DeclineReasonKey LEFT OUTER JOIN AppDeclineReason adr4 ON a.DeclineReasonKey4 = adr1.DeclineReasonKey LEFT OUTER JOIN ( SELECT a.AppKey, arpc.FICODatePulled, arpc.FICOScore AS FICO, arpc.FICODatePulled AS Date_FICO_Pulled, arpcg1.AppRelatedPartyCreditFactorDesc AS FICOFactor1, arpcg2.AppRelatedPartyCreditFactorDesc AS FICOFactor2, arpcg3.AppRelatedPartyCreditFactorDesc AS FICOFactor3, arpcg4.AppRelatedPartyCreditFactorDesc AS FICOFactor4, c1.IsProprietor, bt.BusinessTypeID, bt.BusinessTypeDesc, ROW_NUMBER ( ) OVER (PARTITION BY a.AppKey ORDER BY arpc.RelatedPartyKey ASC) AS rowCnt FROM [Application] a JOIN [Customer] c ON a.CustomerKey = c.CustomerKey JOIN AppRelatedPartyCredit arpc ON a.AppKey = arpc.AppKey JOIN AppRelatedParty arp ON arpc.RelatedPartyKey = arp.RelatedPartyKey JOIN [Customer] c1 ON arp.CustomerKey = c1.CustomerKey JOIN BusinessType bt ON c.BusinessTypeID = bt.BusinessTypeID LEFT OUTER JOIN AppRelatedPartyCreditFactor arpcg1 ON arpc.AppRelatedPartyCreditFactorID1 = arpcg1.AppRelatedPartyCreditFactorID LEFT OUTER JOIN AppRelatedPartyCreditFactor arpcg2 ON arpc.AppRelatedPartyCreditFactorID2 = arpcg2.AppRelatedPartyCreditFactorID LEFT OUTER JOIN AppRelatedPartyCreditFactor arpcg3 ON arpc.AppRelatedPartyCreditFactorID3 = arpcg3.AppRelatedPartyCreditFactorID LEFT OUTER JOIN AppRelatedPartyCreditFactor arpcg4 ON arpc.AppRelatedPartyCreditFactorID4 = arpcg4.AppRelatedPartyCreditFactorID WHERE c.BusinessTypeID = 8 AND c1.IsProprietor = 1 ) AS arpc ON a.AppKey = arpc.AppKey WHERE am.MetricEndDate IS NULL AND dch.HistoryDate >= @beginofDay AND dch.HistoryDate < @endOfDay AND (syn.AppSyndicationStatusId is null or syn.AppSyndicationStatusId = 3) AND (a.CustomerApp = 1 OR ap.PromotionCode = 'PSK' ) AND (ap.PromotionCode = 'PSK' OR al.ProductLineCode = '0022') AND (arpc.rowCnt = 1 OR arpc.rowCnt IS NULL) AND (convert(datetime, convert(varchar(10), a.DecisionDate, 101)) = convert(datetime, convert(varchar(10), dch.HistoryDate, 101)) OR a.DecisionDate > @conversionDate) ORDER BY a.AppKey SELECT * FROM @contracts ORDER BY Sort, REMIT_TODESC, BILLING_NAME