You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
 
 

410 lines
31 KiB

USE [FastMoneyPro_Remit]
GO
/****** Object: StoredProcedure [dbo].[Proc_UKListManagement] Script Date: 2/5/2024 9:31:04 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_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_LIST'
) = CAST(LEFT(@ofacDate, 10) AS DATE)
AND 1 = 2
BEGIN
SELECT 1 ERROR_CODE
,'Current version of UK_LIST is already updated ' mes
,0 AS id
RETURN;
END
ELSE
BEGIN
BEGIN TRANSACTION
pRINT 'a'
--####### 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" or 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'
,NULL AS 'AliasStrength'
INTO #TEMPUNSCRLIST
FROM @xml.nodes('Designations/Designation') T(c)
--print @xmlFile
--SELECT * FROM #TEMPUNSCRLIST
--RETURN
--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" or 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'
,NULL AS 'AliasStrength'
INTO #TEMPENTITYLIST
FROM @xml.nodes('Designations/Designation') T(c)
--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_LIST'
AND sourceEntNum = @source
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 = ISNULL(NATIONALITY, '')
,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, '') +
' 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
,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)
) 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_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_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
);
IF @@TRANCOUNT > 0
COMMIT TRANSACTION
SELECT 0 error_code
,'Sanctions List Data imported successfully' mes
,NULL AS id
END
END
END TRY
BEGIN CATCH
DECLARE @error_message NVARCHAR(MAX) = ERROR_MESSAGE();
DECLARE @error_number INT = ERROR_NUMBER();
DECLARE @error_severity INT = ERROR_SEVERITY();
DECLARE @error_state INT = ERROR_STATE();
SELECT @error_number AS error_code, @error_message AS mes, NULL AS id;
IF @@TRANCOUNT > 0
ROLLBACK TRANSACTION
SELECT 1 error_code
,ERROR_MESSAGE() mes
,NULL AS id
END CATCH