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

  1. USE [FastMoneyPro_Remit]
  2. GO
  3. /****** Object: StoredProcedure [dbo].[Proc_UKListManagement] Script Date: 2/5/2024 9:31:04 PM ******/
  4. SET ANSI_NULLS ON
  5. GO
  6. SET QUOTED_IDENTIFIER ON
  7. GO
  8. ALTER PROCEDURE [dbo].[Proc_UKListManagement] @flag VARCHAR(10)
  9. ,@xmlFile NVARCHAR(MAX)
  10. ,@xmlFileName VARCHAR(100)
  11. ,@user VARCHAR(50)
  12. ,@source VARCHAR(50)
  13. AS
  14. SET NOCOUNT ON;
  15. SET ANSI_NULLS ON;
  16. --#334 : OFAC screening changes.
  17. DECLARE @xml XML
  18. SET @xml = @xmlFile
  19. BEGIN TRY
  20. CREATE TABLE #msg (
  21. errorCode INT
  22. ,msg VARCHAR(100)
  23. ,id INT
  24. )
  25. DECLARE @dataSource VARCHAR(30)
  26. ,@ofacDate VARCHAR(30)
  27. SET @dataSource = 'UK_LIST'
  28. IF @flag = 'ofac-list'
  29. BEGIN
  30. SELECT @ofacDate = T.c.value('@dateGenerated', 'varchar(500)')
  31. FROM @xml.nodes('Designations') T(c)
  32. IF (
  33. SELECT ISNULL(MAX(ofacDate), '2100-1-1')
  34. FROM blacklistLog
  35. WHERE dataSource = 'UK_LIST'
  36. ) = CAST(LEFT(@ofacDate, 10) AS DATE)
  37. AND 1 = 2
  38. BEGIN
  39. SELECT 1 ERROR_CODE
  40. ,'Current version of UK_LIST is already updated ' mes
  41. ,0 AS id
  42. RETURN;
  43. END
  44. ELSE
  45. BEGIN
  46. BEGIN TRANSACTION
  47. pRINT 'a'
  48. --####### INSERTING INDIVIDUAL DATA ON TEMP TABLE ###################################
  49. SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID'
  50. ,T.c.value('OFSIGroupID[1]', 'varchar(500)') AS 'OFSIGroupID'
  51. ,T.c.value('UNReferenceNumber[1]', 'varchar(500)') AS 'UNReferenceNumber'
  52. , STUFF((
  53. SELECT ', ' + ISNULL(Name.value('(Name1)[1]', 'varchar(100)'), '') +
  54. ' ' + ISNULL(Name.value('(Name2)[1]', 'varchar(100)'), '') +
  55. ' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') +
  56. ' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') +
  57. ' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') +
  58. ' ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '')
  59. FROM T.c.nodes('Names/Name[NameType="Primary Name" or NameType="Primary name"]') AS Names(Name)
  60. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'FullName'
  61. ,T.c.value('(NonLatinNames/NonLatinName/NameNonLatinScript)[1]', 'nvarchar(MAX)') AS 'NonLatinName'
  62. ,T.c.value('(Titles/Title)[1]','varchar(500)') AS 'Title'
  63. ,T.c.value('RegimeName[1]', 'varchar(500)') AS 'RegimeName'
  64. ,'UN' AS 'from_file'
  65. ,'I' AS 'indEnt'
  66. ,'' AS 'OTHERFIELDS'
  67. ,T.c.value('IndividualEntityShip[1]', 'varchar(500)') AS 'IndividualEntityShip'
  68. ,T.c.value('DesignationSource[1]', 'varchar(500)') AS 'DesignationSource'
  69. ,T.c.value('SanctionsImposed[1]', 'varchar(500)') AS 'SanctionsImposed'
  70. , STUFF((
  71. SELECT ', ' + DOB.value('.', 'varchar(10)')
  72. FROM T.c.nodes('IndividualDetails/Individual/DOBs/DOB') AS DOBs(DOB)
  73. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'DOBs'
  74. , STUFF((
  75. SELECT ', ' + TownOfBirth.value('.', 'varchar(100)')
  76. FROM T.c.nodes('IndividualDetails/Individual/BirthDetails/Location/TownOfBirth') AS BirthTown(TownOfBirth)
  77. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'BirthTown'
  78. , STUFF((
  79. SELECT ', ' + CountryOfBirth.value('.', 'varchar(50)')
  80. FROM T.c.nodes('IndividualDetails/Individual/BirthDetails/Location/CountryOfBirth') AS BirthCountry(CountryOfBirth)
  81. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'BirthCountry'
  82. , STUFF((
  83. SELECT ', ' + PassportNumber.value('.', 'varchar(50)')
  84. FROM T.c.nodes('IndividualDetails/Individual/PassportDetails/PassportNumber') AS PassportDetails(PassportNumber)
  85. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'PassportNumber'
  86. , STUFF((
  87. SELECT ', ' + PassportAdditionalInformation.value('.', 'varchar(50)')
  88. FROM T.c.nodes('IndividualDetails/Individual/PassportDetails/PassportAdditionalInformation') AS PassportDetails(PassportAdditionalInformation)
  89. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'PassportAdditionalInformation'
  90. , STUFF((
  91. SELECT ', ' + Position.value('.', 'varchar(10)')
  92. FROM T.c.nodes('IndividualDetails/Individual/Positions/Position') AS Positions(Position)
  93. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Position'
  94. ,T.c.value('(IndividualDetails/Individual/Nationalities/Nationality)[1]', 'varchar(50)') AS 'Nationality'
  95. , STUFF((
  96. SELECT ', ' + NationalIdentifierNumber.value('.', 'varchar(10)')
  97. FROM T.c.nodes('IndividualDetails/Individual/NationalIdentifierDetails/NationalIdentifier/NationalIdentifierNumber') AS NationalIdentifier(NationalIdentifierNumber)
  98. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'NID_Num'
  99. , STUFF((
  100. SELECT ', ' + NationalIdentifierAdditionalInformation.value('.', 'varchar(10)')
  101. FROM T.c.nodes('IndividualDetails/Individual/NationalIdentifierDetails/NationalIdentifier/NationalIdentifierAdditionalInformation') AS NationalIdentifier(NationalIdentifierAdditionalInformation)
  102. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'NID_Info'
  103. ,T.c.value('(IndividualDetails/Individual/Genders/Gender)[1]', 'varchar(10)') AS 'Gender'
  104. ,T.c.value('OtherInformation[1]', 'varchar(MAX)') AS 'Remarks'
  105. ,T.c.value('DateDesignated[1]', 'varchar(MAX)') AS 'DateDesignated'
  106. ,T.c.value('LastUpdated[1]', 'varchar(500)') AS 'LastUpdated'
  107. ,NULL AS 'AliasStrength'
  108. INTO #TEMPUNSCRLIST
  109. FROM @xml.nodes('Designations/Designation') T(c)
  110. --print @xmlFile
  111. --SELECT * FROM #TEMPUNSCRLIST
  112. --RETURN
  113. --SELECT * FROM #TEMPINDVALIASNAME
  114. --RETURN
  115. --######################END OF INDIVIDUAL LIST-- ###################################
  116. -- ENTITY
  117. --########## BEGINING OF ENTITY ###############################################
  118. --commented out
  119. SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID'
  120. ,T.c.value('OFSIGroupID[1]', 'varchar(500)') AS 'OFSIGroupID'
  121. ,T.c.value('UNReferenceNumber[1]', 'varchar(500)') AS 'UNReferenceNumber'
  122. , STUFF((
  123. SELECT ', ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '')
  124. FROM T.c.nodes('Names/Name[NameType="Primary Name" or NameType="Primary name"]') AS Names(Name)
  125. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'FullName'
  126. , STUFF((
  127. SELECT ', ' + NonLatinName.value('(NameNonLatinScript)[1]', 'nvarchar(MAX)')
  128. FROM T.c.nodes('NonLatinNames/NonLatinName') AS NonLatinNames(NonLatinName)
  129. FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'NonLatinNames'
  130. ,T.c.value('RegimeName[1]', 'varchar(500)') AS 'RegimeName'
  131. ,'UN' AS 'from_file'
  132. ,'I' AS 'indEnt'
  133. ,'' AS 'OTHERFIELDS'
  134. ,T.c.value('IndividualEntityShip[1]', 'varchar(500)') AS 'IndividualEntityShip'
  135. ,T.c.value('DesignationSource[1]', 'varchar(500)') AS 'DesignationSource'
  136. ,T.c.value('SanctionsImposed[1]', 'varchar(500)') AS 'SanctionsImposed'
  137. , STUFF((
  138. SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') +
  139. ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') +
  140. ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') +
  141. ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') +
  142. ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') +
  143. ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') +
  144. ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') +
  145. ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '')
  146. FROM T.c.nodes('Addresses/Address[1]') AS Addresses(Address)
  147. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'AddressLines'
  148. ,STUFF((
  149. SELECT ', ' + PhoneNumber.value('(PhoneNumber)[1]', 'nvarchar(MAX)'),'' +
  150. ', ' + PhoneNumber.value('(PhoneNumber)[2]', 'nvarchar(MAX)'),'' +
  151. ', ' + PhoneNumber.value('(PhoneNumber)[3]', 'nvarchar(MAX)'),'' +
  152. ', ' + PhoneNumber.value('(PhoneNumber)[4]', 'nvarchar(MAX)'),'' +
  153. ', ' + PhoneNumber.value('(PhoneNumber)[5]', 'nvarchar(MAX)'),'' +
  154. ', ' + PhoneNumber.value('(PhoneNumber)[6]', 'nvarchar(MAX)'),''
  155. FROM T.c.nodes('PhoneNumbers') AS PhoneNumbers(PhoneNumber)
  156. FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'PhoneNumber'
  157. ,STUFF((
  158. SELECT ', ' + EmailAddress.value('(EmailAddress)[1]', 'nvarchar(MAX)')
  159. FROM T.c.nodes('EmailAddresses') AS EmailAddresses(EmailAddress)
  160. FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'EmailAddress'
  161. ,T.c.value('OtherInformation[1]', 'varchar(MAX)') AS 'Remarks'
  162. ,T.c.value('DateDesignated[1]', 'varchar(MAX)') AS 'DateDesignated'
  163. ,T.c.value('LastUpdated[1]', 'varchar(500)') AS 'LastUpdated'
  164. ,NULL AS 'AliasStrength'
  165. INTO #TEMPENTITYLIST
  166. FROM @xml.nodes('Designations/Designation') T(c)
  167. --SELECT * FROM #TEMPENTITYLIST
  168. ----SELECT * FROM #TEMPENTITYNAME
  169. --return
  170. --select * from blacklist where dataSource='UNSCR'
  171. --############# INSERTING DATA ON BLACK LIST ############################################
  172. DELETE
  173. FROM blacklist
  174. --WHERE ENTNUM IN (SELECT DATAID FROM #TEMPUNSCRLIST)
  175. WHERE dataSource = 'UK_LIST'
  176. AND sourceEntNum = @source
  177. INSERT INTO blacklist (
  178. ofacKey
  179. ,entNum
  180. ,name
  181. ,vesselType
  182. ,address
  183. ,city
  184. ,zip
  185. ,country
  186. ,remarks
  187. ,sortOrder
  188. ,fromFile
  189. ,dataSource
  190. ,indEnt
  191. ,sourceEntNum
  192. )
  193. SELECT dataSource + '' + CAST(entNum AS VARCHAR)
  194. ,entNum
  195. ,[NAME]
  196. ,[vesselType]
  197. ,address
  198. ,city
  199. ,zip
  200. ,country
  201. ,remarks
  202. ,[sortOrder]
  203. ,fromFile
  204. ,[dataSource]
  205. ,indEnt
  206. ,sourceEntNum
  207. FROM (
  208. SELECT entNum = UniqueID
  209. ,[NAME] = FullName
  210. ,[vesselType] = 'sdn'
  211. ,address = NULL
  212. ,city = NULL
  213. ,zip = NULL
  214. ,country = ISNULL(NATIONALITY, '')
  215. ,remarks = ISNULL(OFSIGroupID, '') + '/' + ' Designated Date: ' + ISNULL(REPLACE(DateDesignated, 'T00:00:00', ','), '') +
  216. ' Place Of Birth: ' + ISNULL(NULLIF(BirthTown + ', ' + BirthCountry, ', '), '') +
  217. ' Date of birth: ' + ISNULL(REPLACE(DOBs, 'T00:00:00', ','), '') +
  218. ' Title: ' + ISNULL(Title, '') +
  219. ' Gender: ' + ISNULL(Gender, '') +
  220. ' Non Latin Name: ' + ISNULL(NonLatinName, '') +
  221. ' RegimeName: ' + ISNULL(RegimeName, '') +
  222. ' Position: ' + ISNULL(Position, '') +
  223. ' SanctionsImposed: ' + ISNULL(SanctionsImposed, '') +
  224. ' PassportNumber: ' + ISNULL(PassportNumber, '') +
  225. ' PassportAdditionalInformation: ' + ISNULL(PassportAdditionalInformation, '') +
  226. ' NID Number: ' + ISNULL(NID_Num, '') +
  227. ' NID Info: ' + ISNULL(NID_Info, '') +
  228. ' Remarks: ' + ISNULL(REMARKS, '') +
  229. ' UNList Type: ' + ISNULL(IndividualEntityShip, '') +
  230. ' Last Update date: ' + ISNULL(REPLACE(LastUpdated, 'T00:00:00', ','), '') +
  231. ' Reference No: ' + ISNULL(UNReferenceNumber, '') +
  232. ' Designation Source: ' + ISNULL(DesignationSource, '') +
  233. ' Individual EntityShip: ' + ISNULL(IndividualEntityShip, '')
  234. ,[sortOrder] = 1
  235. ,fromFile = @xmlFileName
  236. ,[dataSource] = @dataSource
  237. ,indEnt = INDENT
  238. ,sourceEntNum = @source
  239. FROM #TEMPUNSCRLIST WITH (NOLOCK)
  240. UNION ALL
  241. SELECT UniqueID
  242. ,FullName
  243. ,'sdn' [vesselType]
  244. ,NULL
  245. ,NULL
  246. ,NULL
  247. ,NULL
  248. ,ISNULL(OFSIGroupID, '') +
  249. ' Date Designated: ' + ISNULL(REPLACE(DateDesignated, 'T00:00:00', ','), '') +
  250. ' Non Latin Names: ' + ISNULL(NonLatinNames, '') +
  251. ' Regime Name: ' + ISNULL(RegimeName, '') +
  252. ' Individual EntityShip: ' + ISNULL(IndividualEntityShip, '') +
  253. ' Designation Source: ' + ISNULL(DesignationSource, '') +
  254. ' Sanctions Imposed: ' + ISNULL(SanctionsImposed, '') +
  255. ' Comments: ' + ISNULL(Remarks, '') +
  256. ' Address: ' + ISNULL(NULLIF(AddressLines + ', ' + '', ', '), '') +
  257. --' Address Postal Code: ' + ISNULL(AddressPostalCode, '') +
  258. ' Last updated date: ' + ISNULL(REPLACE(LastUpdated, 'T00:00:00', ','), '') +
  259. ' Reference No: ' + ISNULL(UNReferenceNumber, '') [remarks]
  260. ,1 [sortOrder]
  261. ,@xmlFileName [fromFile]
  262. ,@dataSource [dataSource]
  263. ,INDENT
  264. ,sourceEntNum = @source
  265. FROM #TEMPENTITYLIST WITH (NOLOCK)
  266. ) x
  267. DECLARE @sdnCount INT
  268. SELECT @sdnCount = COUNT(*)
  269. FROM #TEMPUNSCRLIST
  270. --SELECT @sdnCount = @sdnCount + COUNT(*)
  271. --FROM #TEMPENTITYNAME
  272. INSERT INTO blacklistLog (
  273. totalRecord
  274. ,dataSource
  275. ,createdBy
  276. ,createdDate
  277. ,ofacDate
  278. )
  279. SELECT @sdnCount
  280. ,@dataSource + ':' + @source
  281. ,@user
  282. ,GETDATE()
  283. ,CAST(LEFT(@ofacDate, 10) AS DATE)
  284. DROP TABLE #TEMPUNSCRLIST
  285. --DROP TABLE #TEMPINDVALIASNAME
  286. --DROP TABLE #TEMPENTITYNAME
  287. DROP TABLE #TEMPENTITYLIST
  288. MERGE blackListHistory AS blh
  289. USING (
  290. SELECT rowId
  291. ,ofacKey
  292. ,entNum
  293. ,name
  294. ,vesselType
  295. ,address
  296. ,city
  297. ,STATE
  298. ,zip
  299. ,country
  300. ,remarks
  301. ,sortOrder
  302. ,fromFile
  303. ,dataSource
  304. ,indEnt
  305. FROM blacklist WITH (NOLOCK)
  306. WHERE dataSource = 'UK_LIST' /* @dataSource*/
  307. ) AS bl
  308. ON ISNULL(blh.ofacKey, '') = ISNULL(bl.ofacKey, '')
  309. AND ISNULL(blh.entNum, '') = ISNULL(bl.entNum, '')
  310. AND ISNULL(blh.name, '') = ISNULL(bl.name, '')
  311. AND ISNULL(blh.vesselType, '') = ISNULL(bl.vesselType, '')
  312. AND ISNULL(blh.address, '') = ISNULL(bl.address, '')
  313. AND ISNULL(blh.city, '') = ISNULL(bl.city, '')
  314. AND ISNULL(blh.STATE, '') = ISNULL(bl.STATE, '')
  315. AND ISNULL(blh.zip, '') = ISNULL(bl.zip, '')
  316. AND ISNULL(blh.country, '') = ISNULL(bl.country, '')
  317. AND ISNULL(blh.remarks, '') = ISNULL(bl.remarks, '')
  318. AND ISNULL(blh.sortOrder, '') = ISNULL(bl.sortOrder, '')
  319. AND ISNULL(blh.fromFile, '') = ISNULL(bl.fromFile, '')
  320. AND ISNULL(blh.dataSource, '') = ISNULL(bl.dataSource, '')
  321. AND ISNULL(blh.indEnt, '') = ISNULL(bl.indEnt, '')
  322. AND bl.dataSource = 'UK_LIST' --@dataSource
  323. AND sourceEntNum = @source
  324. WHEN NOT MATCHED
  325. THEN
  326. INSERT (
  327. blackListId
  328. ,ofacKey
  329. ,entNum
  330. ,name
  331. ,vesselType
  332. ,address
  333. ,city
  334. ,STATE
  335. ,zip
  336. ,country
  337. ,remarks
  338. ,sortOrder
  339. ,fromFile
  340. ,dataSource
  341. ,indEnt
  342. )
  343. VALUES (
  344. bl.rowId
  345. ,bl.ofacKey
  346. ,bl.entNum
  347. ,bl.name
  348. ,bl.vesselType
  349. ,bl.address
  350. ,bl.city
  351. ,bl.STATE
  352. ,bl.zip
  353. ,bl.country
  354. ,bl.remarks
  355. ,bl.sortOrder
  356. ,bl.fromFile
  357. ,bl.dataSource
  358. ,bl.indEnt
  359. );
  360. IF @@TRANCOUNT > 0
  361. COMMIT TRANSACTION
  362. SELECT 0 error_code
  363. ,'Sanctions List Data imported successfully' mes
  364. ,NULL AS id
  365. END
  366. END
  367. END TRY
  368. BEGIN CATCH
  369. DECLARE @error_message NVARCHAR(MAX) = ERROR_MESSAGE();
  370. DECLARE @error_number INT = ERROR_NUMBER();
  371. DECLARE @error_severity INT = ERROR_SEVERITY();
  372. DECLARE @error_state INT = ERROR_STATE();
  373. SELECT @error_number AS error_code, @error_message AS mes, NULL AS id;
  374. IF @@TRANCOUNT > 0
  375. ROLLBACK TRANSACTION
  376. SELECT 1 error_code
  377. ,ERROR_MESSAGE() mes
  378. ,NULL AS id
  379. END CATCH