From f6d3107409ea00118ed7889e94db14752ed88f09 Mon Sep 17 00:00:00 2001 From: Leeza Baidar Date: Thu, 31 Aug 2023 22:36:30 +0545 Subject: [PATCH] #16223 OFAC DATA import --- StoredProc/ofac/Proc_UKListManagement.sql | 632 ++++++++++++++++++++++ 1 file changed, 632 insertions(+) create mode 100644 StoredProc/ofac/Proc_UKListManagement.sql diff --git a/StoredProc/ofac/Proc_UKListManagement.sql b/StoredProc/ofac/Proc_UKListManagement.sql new file mode 100644 index 0000000..0538ca1 --- /dev/null +++ b/StoredProc/ofac/Proc_UKListManagement.sql @@ -0,0 +1,632 @@ + +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO +USE [FastMoneyPro_Remit] +GO +/****** Object: StoredProcedure [dbo].[Proc_UKListManagement] Script Date: 8/31/2023 9:22:05 PM ******/ +SET ANSI_NULLS ON +GO +SET QUOTED_IDENTIFIER ON +GO + +ALTER PROCEDURE [dbo].[Proc_UKListManagement] @flag VARCHAR(10) + ,@xmlFile NVARCHAR(MAX) + ,@xmlFileName VARCHAR(100) + ,@user VARCHAR(50) + ,@source VARCHAR(50) +AS +SET NOCOUNT ON; +SET ANSI_NULLS ON; + +--#334 : OFAC screening changes. +DECLARE @xml XML + +SET @xml = @xmlFile + +BEGIN TRY + CREATE TABLE #msg ( + errorCode INT + ,msg VARCHAR(100) + ,id INT + ) + + DECLARE @dataSource VARCHAR(30) + ,@ofacDate VARCHAR(30) + + SET @dataSource = 'UK_Saction_List' + + IF @flag = 'ofac-list' + BEGIN + SELECT @ofacDate = T.c.value('@dateGenerated', 'varchar(500)') + FROM @xml.nodes('Designations') T(c) + + IF ( + SELECT ISNULL(MAX(ofacDate), '2100-1-1') + FROM blacklistLog + WHERE dataSource = 'UK_Saction_List' + ) = CAST(LEFT(@ofacDate, 10) AS DATE) + AND 1 = 2 + BEGIN + SELECT 1 ERROR_CODE + ,'Current version of UK_Saction_List is already updated ' mes + ,0 AS id + + RETURN; + END + ELSE + BEGIN + BEGIN TRANSACTION + + --####### INSERTING INDIVIDUAL DATA ON TEMP TABLE ################################### + SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID' + ,T.c.value('OFSIGroupID[1]', 'varchar(500)') AS 'OFSIGroupID' + ,T.c.value('UNReferenceNumber[1]', 'varchar(500)') AS 'UNReferenceNumber' + , STUFF(( + SELECT ', ' + ISNULL(Name.value('(Name1)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Name.value('(Name2)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '') + FROM T.c.nodes('Names/Name[NameType="Primary Name"]') AS Names(Name) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'FullName' + ,T.c.value('(NonLatinNames/NonLatinName/NameNonLatinScript)[1]', 'nvarchar(MAX)') AS 'NonLatinName' + ,T.c.value('(Titles/Title)[1]','varchar(500)') AS 'Title' + ,T.c.value('RegimeName[1]', 'varchar(500)') AS 'RegimeName' + ,'UN' AS 'from_file' + ,'I' AS 'indEnt' + ,'' AS 'OTHERFIELDS' + ,T.c.value('IndividualEntityShip[1]', 'varchar(500)') AS 'IndividualEntityShip' + ,T.c.value('DesignationSource[1]', 'varchar(500)') AS 'DesignationSource' + ,T.c.value('SanctionsImposed[1]', 'varchar(500)') AS 'SanctionsImposed' + , STUFF(( + SELECT ', ' + DOB.value('.', 'varchar(10)') + FROM T.c.nodes('IndividualDetails/Individual/DOBs/DOB') AS DOBs(DOB) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'DOBs' + , STUFF(( + SELECT ', ' + TownOfBirth.value('.', 'varchar(100)') + FROM T.c.nodes('IndividualDetails/Individual/BirthDetails/Location/TownOfBirth') AS BirthTown(TownOfBirth) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'BirthTown' + , STUFF(( + SELECT ', ' + CountryOfBirth.value('.', 'varchar(50)') + FROM T.c.nodes('IndividualDetails/Individual/BirthDetails/Location/CountryOfBirth') AS BirthCountry(CountryOfBirth) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'BirthCountry' + , STUFF(( + SELECT ', ' + PassportNumber.value('.', 'varchar(50)') + FROM T.c.nodes('IndividualDetails/Individual/PassportDetails/PassportNumber') AS PassportDetails(PassportNumber) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'PassportNumber' + , STUFF(( + SELECT ', ' + PassportAdditionalInformation.value('.', 'varchar(50)') + FROM T.c.nodes('IndividualDetails/Individual/PassportDetails/PassportAdditionalInformation') AS PassportDetails(PassportAdditionalInformation) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'PassportAdditionalInformation' + , STUFF(( + SELECT ', ' + Position.value('.', 'varchar(10)') + FROM T.c.nodes('IndividualDetails/Individual/Positions/Position') AS Positions(Position) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Position' + ,T.c.value('(IndividualDetails/Individual/Nationalities/Nationality)[1]', 'varchar(50)') AS 'Nationality' + , STUFF(( + SELECT ', ' + NationalIdentifierNumber.value('.', 'varchar(10)') + FROM T.c.nodes('IndividualDetails/Individual/NationalIdentifierDetails/NationalIdentifier/NationalIdentifierNumber') AS NationalIdentifier(NationalIdentifierNumber) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'NID_Num' + , STUFF(( + SELECT ', ' + NationalIdentifierAdditionalInformation.value('.', 'varchar(10)') + FROM T.c.nodes('IndividualDetails/Individual/NationalIdentifierDetails/NationalIdentifier/NationalIdentifierAdditionalInformation') AS NationalIdentifier(NationalIdentifierAdditionalInformation) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'NID_Info' + ,T.c.value('(IndividualDetails/Individual/Genders/Gender)[1]', 'varchar(10)') AS 'Gender' + ,T.c.value('OtherInformation[1]', 'varchar(MAX)') AS 'Remarks' + ,T.c.value('DateDesignated[1]', 'varchar(MAX)') AS 'DateDesignated' + ,T.c.value('LastUpdated[1]', 'varchar(500)') AS 'LastUpdated' + INTO #TEMPUNSCRLIST + FROM @xml.nodes('Designations/Designation') T(c) + + + --SELECT * FROM #TEMPUNSCRLIST + --alias data + --SELECT * + --INTO #TEMPINDVALIASNAME + --FROM ( + -- SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID', + -- STUFF(( + -- SELECT ', ' + ISNULL(Name.value('(Name1)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Name.value('(Name2)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '') + -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name) + -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1' + -- FROM @xml.nodes('Designations/Designation') AS T(c) + + -- --UNION ALL + + -- --SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID', + -- --STUFF(( + -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[2]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name2)[2]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name6)[2]', 'varchar(100)'), '') + -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name) + -- -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1' + -- -- FROM @xml.nodes('Designations/Designation') AS T(c) + + -- --UNION ALL + + -- --SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID', + -- --STUFF(( + -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[3]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name2)[3]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name6)[3]', 'varchar(100)'), '') + -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name) + -- -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1' + -- -- FROM @xml.nodes('Designations/Designation') AS T(c) + + -- --UNION ALL + + -- --SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID', + -- --STUFF(( + -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[4]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name2)[4]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') + + -- -- --' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name6)[4]', 'varchar(100)'), '') + -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name) + -- -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1' + -- -- FROM @xml.nodes('Designations/Designation') AS T(c) + + -- --UNION ALL + + -- --SELECT + -- -- T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID', + -- -- STUFF(( + -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[6]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name2)[6]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name6)[6]', 'varchar(100)'), '') + -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Name(Name) + -- -- FOR XML PATH(''), TYPE + -- -- ).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1' + -- --FROM @xml.nodes('Designations/Designation') AS T(c) + + -- --UNION ALL + + -- --SELECT + -- -- T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID', + -- -- STUFF(( + -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[7]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name2)[7]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name6)[7]', 'varchar(100)'), '') + -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Name(Name) + -- -- FOR XML PATH(''), TYPE + -- -- ).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1' + -- --FROM @xml.nodes('Designations/Designation') AS T(c) + + -- --UNION ALL + + -- --SELECT + -- -- T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID', + -- -- STUFF(( + -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[8]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name2)[8]', 'varchar(100)'), '') + + -- -- ' ' + ISNULL(Name.value('(Name6)[8]', 'varchar(100)'), '') + -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Name(Name) + -- -- FOR XML PATH(''), TYPE + -- -- ).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1' + -- --FROM @xml.nodes('Designations/Designation') AS T(c) + -- ) X + + --SELECT * FROM #TEMPINDVALIASNAME + --RETURN + --######################END OF INDIVIDUAL LIST-- ################################### + -- ENTITY + --########## BEGINING OF ENTITY ############################################### + --commented out + SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID' + ,T.c.value('OFSIGroupID[1]', 'varchar(500)') AS 'OFSIGroupID' + ,T.c.value('UNReferenceNumber[1]', 'varchar(500)') AS 'UNReferenceNumber' + , STUFF(( + SELECT ', ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '') + FROM T.c.nodes('Names/Name[NameType="Primary Name"]') AS Names(Name) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'FullName' + , STUFF(( + SELECT ', ' + NonLatinName.value('(NameNonLatinScript)[1]', 'nvarchar(MAX)') + FROM T.c.nodes('NonLatinNames/NonLatinName') AS NonLatinNames(NonLatinName) + FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'NonLatinNames' + ,T.c.value('RegimeName[1]', 'varchar(500)') AS 'RegimeName' + ,'UN' AS 'from_file' + ,'I' AS 'indEnt' + ,'' AS 'OTHERFIELDS' + ,T.c.value('IndividualEntityShip[1]', 'varchar(500)') AS 'IndividualEntityShip' + ,T.c.value('DesignationSource[1]', 'varchar(500)') AS 'DesignationSource' + ,T.c.value('SanctionsImposed[1]', 'varchar(500)') AS 'SanctionsImposed' + , STUFF(( + SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') + + ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '') + FROM T.c.nodes('Addresses/Address[1]') AS Addresses(Address) + FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'AddressLines' + ,STUFF(( + SELECT ', ' + PhoneNumber.value('(PhoneNumber)[1]', 'nvarchar(MAX)'),'' + + ', ' + PhoneNumber.value('(PhoneNumber)[2]', 'nvarchar(MAX)'),'' + + ', ' + PhoneNumber.value('(PhoneNumber)[3]', 'nvarchar(MAX)'),'' + + ', ' + PhoneNumber.value('(PhoneNumber)[4]', 'nvarchar(MAX)'),'' + + ', ' + PhoneNumber.value('(PhoneNumber)[5]', 'nvarchar(MAX)'),'' + + ', ' + PhoneNumber.value('(PhoneNumber)[6]', 'nvarchar(MAX)'),'' + FROM T.c.nodes('PhoneNumbers') AS PhoneNumbers(PhoneNumber) + FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'PhoneNumber' + ,STUFF(( + SELECT ', ' + EmailAddress.value('(EmailAddress)[1]', 'nvarchar(MAX)') + FROM T.c.nodes('EmailAddresses') AS EmailAddresses(EmailAddress) + FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'EmailAddress' + ,T.c.value('OtherInformation[1]', 'varchar(MAX)') AS 'Remarks' + ,T.c.value('DateDesignated[1]', 'varchar(MAX)') AS 'DateDesignated' + ,T.c.value('LastUpdated[1]', 'varchar(500)') AS 'LastUpdated' + INTO #TEMPENTITYLIST + FROM @xml.nodes('Designations/Designation') T(c) + + --SELECT * FROM #TEMPENTITYLIST + --SELECT * + --INTO #TEMPENTITYNAME + --FROM ( + -- SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID' + -- ,N.c.value('(Name6)[1]', 'varchar(100)') AS 'Alias_FullName2' + -- , STUFF(( + -- SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '') + -- FROM T.c.nodes('Addresses/Address') AS Addresses(Address) + -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_AddressLines2' + -- FROM @xml.nodes('Designations/Designation') T(c) + -- CROSS APPLY T.c.nodes('Names/Name[NameType="Alias"]') AS N(c) + + --UNION ALL + + --SELECT + -- T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID', + -- N.c.value('(Name6)[1]', 'varchar(100)') AS 'Alias_FullName2', + -- STUFF(( + -- SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '') + -- FROM T.c.nodes('Addresses/Address[2]') AS Addresses(Address) + -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_AddressLines2' + --FROM @xml.nodes('Designations/Designation') AS T(c) + --CROSS APPLY T.c.nodes('Names/Name[NameType="Alias"]') AS N(c) + + --UNION ALL + + --SELECT + -- T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID', + -- N.c.value('(Name6)[1]', 'varchar(100)') AS 'Alias_FullName2', + -- STUFF(( + -- SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') + + -- ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '') + -- FROM T.c.nodes('Addresses/Address[3]') AS Addresses(Address) + -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_AddressLines2' + --FROM @xml.nodes('Designations/Designation') AS T(c) + --CROSS APPLY T.c.nodes('Names/Name[NameType="Alias"]') AS N(c) + --) x + + --SELECT * FROM #TEMPENTITYLIST + --SELECT * FROM #TEMPENTITYNAME + --return + --select * from blacklist where dataSource='UNSCR' + --############# INSERTING DATA ON BLACK LIST ############################################ + DELETE + FROM blacklist + --WHERE ENTNUM IN (SELECT DATAID FROM #TEMPUNSCRLIST) + WHERE dataSource = 'UK_Saction_List' + AND sourceEntNum = @source + + --DELETE FROM blacklistHISTORY + --WHERE ENTNUM IN (SELECT DATAID FROM #TEMPUNSCRLIST) + --AND dataSource='UNSCR' + INSERT INTO blacklist ( + ofacKey + ,entNum + ,name + ,vesselType + ,address + ,city + ,zip + ,country + ,remarks + ,sortOrder + ,fromFile + ,dataSource + ,indEnt + ,sourceEntNum + ) + SELECT dataSource + '' + CAST(entNum AS VARCHAR) + ,entNum + ,[NAME] + ,[vesselType] + ,address + ,city + ,zip + ,country + ,remarks + ,[sortOrder] + ,fromFile + ,[dataSource] + ,indEnt + ,sourceEntNum + FROM ( + SELECT entNum = UniqueID + ,[NAME] = FullName + ,[vesselType] = 'sdn' + ,address = NULL + ,city = NULL + ,zip = NULL + ,country = NULL + ,remarks = ISNULL(OFSIGroupID, '') + '/' + ' Designated Date: ' + ISNULL(REPLACE(DateDesignated, 'T00:00:00', ','), '') + + ' Place Of Birth: ' + ISNULL(NULLIF(BirthTown + ', ' + BirthCountry, ', '), '') + + ' Date of birth: ' + ISNULL(REPLACE(DOBs, 'T00:00:00', ','), '') + + ' Title: ' + ISNULL(Title, '') + + ' Nationality: ' + ISNULL(NATIONALITY, '') + + ' Gender: ' + ISNULL(Gender, '') + + ' Non Latin Name: ' + ISNULL(NonLatinName, '') + + ' RegimeName: ' + ISNULL(RegimeName, '') + + ' Position: ' + ISNULL(Position, '') + + ' SanctionsImposed: ' + ISNULL(SanctionsImposed, '') + + ' PassportNumber: ' + ISNULL(PassportNumber, '') + + ' PassportAdditionalInformation: ' + ISNULL(PassportAdditionalInformation, '') + + ' NID Number: ' + ISNULL(NID_Num, '') + + ' NID Info: ' + ISNULL(NID_Info, '') + + ' Remarks: ' + ISNULL(REMARKS, '') + + ' UNList Type: ' + ISNULL(IndividualEntityShip, '') + + ' Last Update date: ' + ISNULL(REPLACE(LastUpdated, 'T00:00:00', ','), '') + + ' Reference No: ' + ISNULL(UNReferenceNumber, '') + + ' Designation Source: ' + ISNULL(DesignationSource, '') + + ' Individual EntityShip: ' + ISNULL(IndividualEntityShip, '') + + ,[sortOrder] = 1 + ,fromFile = @xmlFileName + ,[dataSource] = @dataSource + ,indEnt = INDENT + ,sourceEntNum = @source + FROM #TEMPUNSCRLIST WITH (NOLOCK) + + -- UNION ALL + + -- SELECT UniqueID + -- --,REPLACE(REPLACE(Alias_FullName1, '? ', ''), '?', '') + -- ,Alias_FullName1 + -- ,'alt' + -- ,NULL + -- ,NULL + -- ,NULL + -- ,NULL + -- ,NULL + -- ,2 + -- ,@xmlFileName [fromFile] + -- ,@dataSource [dataSource] + -- ,'I' + -- ,sourceEntNum = @source + -- FROM #TEMPINDVALIASNAME + -- WHERE Alias_FullName1 IS NOT NULL + -- AND Alias_FullName1 IS NOT NULL + ----ISNULL(REPLACE(REPLACE(Alias_FullName1, '? ', ''), '?', ''), 'B') <> 'B' + + UNION ALL + + SELECT UniqueID + ,FullName + ,'sdn' [vesselType] + ,NULL + ,NULL + ,NULL + ,NULL + ,ISNULL(OFSIGroupID, '') + + ' Date Designated: ' + ISNULL(REPLACE(DateDesignated, 'T00:00:00', ','), '') + + ' Non Latin Names: ' + ISNULL(NonLatinNames, '') + + ' Regime Name: ' + ISNULL(RegimeName, '') + + ' Individual EntityShip: ' + ISNULL(IndividualEntityShip, '') + + ' Designation Source: ' + ISNULL(DesignationSource, '') + + ' Sanctions Imposed: ' + ISNULL(SanctionsImposed, '') + + ' Comments: ' + ISNULL(Remarks, '') + + ' Address: ' + ISNULL(NULLIF(AddressLines + ', ' + '', ', '), '') + + --' Address Postal Code: ' + ISNULL(AddressPostalCode, '') + + ' Last updated date: ' + ISNULL(REPLACE(LastUpdated, 'T00:00:00', ','), '') + + ' Reference No: ' + ISNULL(UNReferenceNumber, '') [remarks] + ,1 [sortOrder] + ,@xmlFileName [fromFile] + ,@dataSource [dataSource] + ,INDENT + ,sourceEntNum = @source + FROM #TEMPENTITYLIST WITH (NOLOCK) + + --UNION ALL + + --SELECT UniqueID + -- ,Alias_FullName2 + -- ,'alt' + -- ,NULL + -- ,NULL + -- ,NULL + -- ,NULL + -- ,NULL + -- ,2 + -- ,@xmlFileName [fromFile] + -- ,@dataSource [dataSource] + -- ,'E' + -- ,sourceEntNum = @source + --FROM #TEMPENTITYNAME + --WHERE Alias_FullName2 IS NOT NULL + + --UNION ALL + + --SELECT UniqueID + -- ,NULL + -- ,'add' + -- ,Alias_AddressLines2 + -- ,NULL + -- ,NULL--Alias_AddressPostalCode2 + -- ,NULL--Alias_AddressCountry2 + -- ,NULL + -- ,3 + -- ,@xmlFileName [fromFile] + -- ,@dataSource [dataSource] + -- ,'E' + -- ,sourceEntNum = @source + --FROM #TEMPENTITYNAME + --WHERE --( + -- Alias_AddressLines2 IS NOT NULL + -- --OR Alias_AddressPostalCode2 IS NOT NULL + -- --OR Alias_AddressCountry2 IS NOT NULL + -- --) + ) x + + DECLARE @sdnCount INT + + SELECT @sdnCount = COUNT(*) + FROM #TEMPUNSCRLIST + + --SELECT @sdnCount = @sdnCount + COUNT(*) + --FROM #TEMPENTITYNAME + + INSERT INTO blacklistLog ( + totalRecord + ,dataSource + ,createdBy + ,createdDate + ,ofacDate + ) + SELECT @sdnCount + ,@dataSource + ':' + @source + ,@user + ,GETDATE() + ,CAST(LEFT(@ofacDate, 10) AS DATE) + + DROP TABLE #TEMPUNSCRLIST + + --DROP TABLE #TEMPINDVALIASNAME + + --DROP TABLE #TEMPENTITYNAME + + DROP TABLE #TEMPENTITYLIST + + MERGE blackListHistory AS blh + USING ( + SELECT rowId + ,ofacKey + ,entNum + ,name + ,vesselType + ,address + ,city + ,STATE + ,zip + ,country + ,remarks + ,sortOrder + ,fromFile + ,dataSource + ,indEnt + FROM blacklist WITH (NOLOCK) + WHERE dataSource = 'UK_Saction_List' /* @dataSource*/ + ) AS bl + ON ISNULL(blh.ofacKey, '') = ISNULL(bl.ofacKey, '') + AND ISNULL(blh.entNum, '') = ISNULL(bl.entNum, '') + AND ISNULL(blh.name, '') = ISNULL(bl.name, '') + AND ISNULL(blh.vesselType, '') = ISNULL(bl.vesselType, '') + AND ISNULL(blh.address, '') = ISNULL(bl.address, '') + AND ISNULL(blh.city, '') = ISNULL(bl.city, '') + AND ISNULL(blh.STATE, '') = ISNULL(bl.STATE, '') + AND ISNULL(blh.zip, '') = ISNULL(bl.zip, '') + AND ISNULL(blh.country, '') = ISNULL(bl.country, '') + AND ISNULL(blh.remarks, '') = ISNULL(bl.remarks, '') + AND ISNULL(blh.sortOrder, '') = ISNULL(bl.sortOrder, '') + AND ISNULL(blh.fromFile, '') = ISNULL(bl.fromFile, '') + AND ISNULL(blh.dataSource, '') = ISNULL(bl.dataSource, '') + AND ISNULL(blh.indEnt, '') = ISNULL(bl.indEnt, '') + AND bl.dataSource = 'UK_Saction_List' --@dataSource + AND sourceEntNum = @source + WHEN NOT MATCHED + THEN + INSERT ( + blackListId + ,ofacKey + ,entNum + ,name + ,vesselType + ,address + ,city + ,STATE + ,zip + ,country + ,remarks + ,sortOrder + ,fromFile + ,dataSource + ,indEnt + ) + VALUES ( + bl.rowId + ,bl.ofacKey + ,bl.entNum + ,bl.name + ,bl.vesselType + ,bl.address + ,bl.city + ,bl.STATE + ,bl.zip + ,bl.country + ,bl.remarks + ,bl.sortOrder + ,bl.fromFile + ,bl.dataSource + ,bl.indEnt + ); + + --INSERT INTO blacklistHistory (blackListId,entNum,name,vesselType,address,city,zip,country,remarks,sortOrder,fromFile,dataSource,indEnt) + --SELECT rowId,entNum,name,vesselType,address,city,zip,country,remarks,sortOrder,fromFile,dataSource,indEnt + --FROM blacklist WITH(NOLOCK) WHERE dataSource='UNSCR' + IF @@TRANCOUNT > 0 + COMMIT TRANSACTION + + SELECT 0 error_code + ,'Sanctions List Data imported successfully' mes + ,NULL AS id + --EXEC PROC_UPDATE_METAPHONE + END + END + --- ENTITY CLOSE +END TRY + +BEGIN CATCH + IF @@TRANCOUNT > 0 + ROLLBACK TRANSACTION + + SELECT 1 error_code + ,ERROR_MESSAGE() mes + ,NULL AS id +END CATCH +