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.

632 lines
25 KiB

  1. SET ANSI_NULLS ON
  2. GO
  3. SET QUOTED_IDENTIFIER ON
  4. GO
  5. USE [FastMoneyPro_Remit]
  6. GO
  7. /****** Object: StoredProcedure [dbo].[Proc_UKListManagement] Script Date: 8/31/2023 9:22:05 PM ******/
  8. SET ANSI_NULLS ON
  9. GO
  10. SET QUOTED_IDENTIFIER ON
  11. GO
  12. ALTER PROCEDURE [dbo].[Proc_UKListManagement] @flag VARCHAR(10)
  13. ,@xmlFile NVARCHAR(MAX)
  14. ,@xmlFileName VARCHAR(100)
  15. ,@user VARCHAR(50)
  16. ,@source VARCHAR(50)
  17. AS
  18. SET NOCOUNT ON;
  19. SET ANSI_NULLS ON;
  20. --#334 : OFAC screening changes.
  21. DECLARE @xml XML
  22. SET @xml = @xmlFile
  23. BEGIN TRY
  24. CREATE TABLE #msg (
  25. errorCode INT
  26. ,msg VARCHAR(100)
  27. ,id INT
  28. )
  29. DECLARE @dataSource VARCHAR(30)
  30. ,@ofacDate VARCHAR(30)
  31. SET @dataSource = 'UK_Saction_List'
  32. IF @flag = 'ofac-list'
  33. BEGIN
  34. SELECT @ofacDate = T.c.value('@dateGenerated', 'varchar(500)')
  35. FROM @xml.nodes('Designations') T(c)
  36. IF (
  37. SELECT ISNULL(MAX(ofacDate), '2100-1-1')
  38. FROM blacklistLog
  39. WHERE dataSource = 'UK_Saction_List'
  40. ) = CAST(LEFT(@ofacDate, 10) AS DATE)
  41. AND 1 = 2
  42. BEGIN
  43. SELECT 1 ERROR_CODE
  44. ,'Current version of UK_Saction_List is already updated ' mes
  45. ,0 AS id
  46. RETURN;
  47. END
  48. ELSE
  49. BEGIN
  50. BEGIN TRANSACTION
  51. --####### INSERTING INDIVIDUAL DATA ON TEMP TABLE ###################################
  52. SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID'
  53. ,T.c.value('OFSIGroupID[1]', 'varchar(500)') AS 'OFSIGroupID'
  54. ,T.c.value('UNReferenceNumber[1]', 'varchar(500)') AS 'UNReferenceNumber'
  55. , STUFF((
  56. SELECT ', ' + ISNULL(Name.value('(Name1)[1]', 'varchar(100)'), '') +
  57. ' ' + ISNULL(Name.value('(Name2)[1]', 'varchar(100)'), '') +
  58. ' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') +
  59. ' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') +
  60. ' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') +
  61. ' ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '')
  62. FROM T.c.nodes('Names/Name[NameType="Primary Name"]') AS Names(Name)
  63. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'FullName'
  64. ,T.c.value('(NonLatinNames/NonLatinName/NameNonLatinScript)[1]', 'nvarchar(MAX)') AS 'NonLatinName'
  65. ,T.c.value('(Titles/Title)[1]','varchar(500)') AS 'Title'
  66. ,T.c.value('RegimeName[1]', 'varchar(500)') AS 'RegimeName'
  67. ,'UN' AS 'from_file'
  68. ,'I' AS 'indEnt'
  69. ,'' AS 'OTHERFIELDS'
  70. ,T.c.value('IndividualEntityShip[1]', 'varchar(500)') AS 'IndividualEntityShip'
  71. ,T.c.value('DesignationSource[1]', 'varchar(500)') AS 'DesignationSource'
  72. ,T.c.value('SanctionsImposed[1]', 'varchar(500)') AS 'SanctionsImposed'
  73. , STUFF((
  74. SELECT ', ' + DOB.value('.', 'varchar(10)')
  75. FROM T.c.nodes('IndividualDetails/Individual/DOBs/DOB') AS DOBs(DOB)
  76. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'DOBs'
  77. , STUFF((
  78. SELECT ', ' + TownOfBirth.value('.', 'varchar(100)')
  79. FROM T.c.nodes('IndividualDetails/Individual/BirthDetails/Location/TownOfBirth') AS BirthTown(TownOfBirth)
  80. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'BirthTown'
  81. , STUFF((
  82. SELECT ', ' + CountryOfBirth.value('.', 'varchar(50)')
  83. FROM T.c.nodes('IndividualDetails/Individual/BirthDetails/Location/CountryOfBirth') AS BirthCountry(CountryOfBirth)
  84. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'BirthCountry'
  85. , STUFF((
  86. SELECT ', ' + PassportNumber.value('.', 'varchar(50)')
  87. FROM T.c.nodes('IndividualDetails/Individual/PassportDetails/PassportNumber') AS PassportDetails(PassportNumber)
  88. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'PassportNumber'
  89. , STUFF((
  90. SELECT ', ' + PassportAdditionalInformation.value('.', 'varchar(50)')
  91. FROM T.c.nodes('IndividualDetails/Individual/PassportDetails/PassportAdditionalInformation') AS PassportDetails(PassportAdditionalInformation)
  92. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'PassportAdditionalInformation'
  93. , STUFF((
  94. SELECT ', ' + Position.value('.', 'varchar(10)')
  95. FROM T.c.nodes('IndividualDetails/Individual/Positions/Position') AS Positions(Position)
  96. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Position'
  97. ,T.c.value('(IndividualDetails/Individual/Nationalities/Nationality)[1]', 'varchar(50)') AS 'Nationality'
  98. , STUFF((
  99. SELECT ', ' + NationalIdentifierNumber.value('.', 'varchar(10)')
  100. FROM T.c.nodes('IndividualDetails/Individual/NationalIdentifierDetails/NationalIdentifier/NationalIdentifierNumber') AS NationalIdentifier(NationalIdentifierNumber)
  101. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'NID_Num'
  102. , STUFF((
  103. SELECT ', ' + NationalIdentifierAdditionalInformation.value('.', 'varchar(10)')
  104. FROM T.c.nodes('IndividualDetails/Individual/NationalIdentifierDetails/NationalIdentifier/NationalIdentifierAdditionalInformation') AS NationalIdentifier(NationalIdentifierAdditionalInformation)
  105. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'NID_Info'
  106. ,T.c.value('(IndividualDetails/Individual/Genders/Gender)[1]', 'varchar(10)') AS 'Gender'
  107. ,T.c.value('OtherInformation[1]', 'varchar(MAX)') AS 'Remarks'
  108. ,T.c.value('DateDesignated[1]', 'varchar(MAX)') AS 'DateDesignated'
  109. ,T.c.value('LastUpdated[1]', 'varchar(500)') AS 'LastUpdated'
  110. INTO #TEMPUNSCRLIST
  111. FROM @xml.nodes('Designations/Designation') T(c)
  112. --SELECT * FROM #TEMPUNSCRLIST
  113. --alias data
  114. --SELECT *
  115. --INTO #TEMPINDVALIASNAME
  116. --FROM (
  117. -- SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID',
  118. -- STUFF((
  119. -- SELECT ', ' + ISNULL(Name.value('(Name1)[1]', 'varchar(100)'), '') +
  120. -- ' ' + ISNULL(Name.value('(Name2)[1]', 'varchar(100)'), '') +
  121. -- ' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') +
  122. -- ' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') +
  123. -- ' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') +
  124. -- ' ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '')
  125. -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name)
  126. -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1'
  127. -- FROM @xml.nodes('Designations/Designation') AS T(c)
  128. -- --UNION ALL
  129. -- --SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID',
  130. -- --STUFF((
  131. -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[2]', 'varchar(100)'), '') +
  132. -- -- ' ' + ISNULL(Name.value('(Name2)[2]', 'varchar(100)'), '') +
  133. -- -- --' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') +
  134. -- -- --' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') +
  135. -- -- --' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') +
  136. -- -- ' ' + ISNULL(Name.value('(Name6)[2]', 'varchar(100)'), '')
  137. -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name)
  138. -- -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1'
  139. -- -- FROM @xml.nodes('Designations/Designation') AS T(c)
  140. -- --UNION ALL
  141. -- --SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID',
  142. -- --STUFF((
  143. -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[3]', 'varchar(100)'), '') +
  144. -- -- ' ' + ISNULL(Name.value('(Name2)[3]', 'varchar(100)'), '') +
  145. -- -- --' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') +
  146. -- -- --' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') +
  147. -- -- --' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') +
  148. -- -- ' ' + ISNULL(Name.value('(Name6)[3]', 'varchar(100)'), '')
  149. -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name)
  150. -- -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1'
  151. -- -- FROM @xml.nodes('Designations/Designation') AS T(c)
  152. -- --UNION ALL
  153. -- --SELECT T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID',
  154. -- --STUFF((
  155. -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[4]', 'varchar(100)'), '') +
  156. -- -- ' ' + ISNULL(Name.value('(Name2)[4]', 'varchar(100)'), '') +
  157. -- -- --' ' + ISNULL(Name.value('(Name3)[1]', 'varchar(100)'), '') +
  158. -- -- --' ' + ISNULL(Name.value('(Name4)[1]', 'varchar(100)'), '') +
  159. -- -- --' ' + ISNULL(Name.value('(Name5)[1]', 'varchar(100)'), '') +
  160. -- -- ' ' + ISNULL(Name.value('(Name6)[4]', 'varchar(100)'), '')
  161. -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Names(Name)
  162. -- -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1'
  163. -- -- FROM @xml.nodes('Designations/Designation') AS T(c)
  164. -- --UNION ALL
  165. -- --SELECT
  166. -- -- T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID',
  167. -- -- STUFF((
  168. -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[6]', 'varchar(100)'), '') +
  169. -- -- ' ' + ISNULL(Name.value('(Name2)[6]', 'varchar(100)'), '') +
  170. -- -- ' ' + ISNULL(Name.value('(Name6)[6]', 'varchar(100)'), '')
  171. -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Name(Name)
  172. -- -- FOR XML PATH(''), TYPE
  173. -- -- ).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1'
  174. -- --FROM @xml.nodes('Designations/Designation') AS T(c)
  175. -- --UNION ALL
  176. -- --SELECT
  177. -- -- T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID',
  178. -- -- STUFF((
  179. -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[7]', 'varchar(100)'), '') +
  180. -- -- ' ' + ISNULL(Name.value('(Name2)[7]', 'varchar(100)'), '') +
  181. -- -- ' ' + ISNULL(Name.value('(Name6)[7]', 'varchar(100)'), '')
  182. -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Name(Name)
  183. -- -- FOR XML PATH(''), TYPE
  184. -- -- ).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1'
  185. -- --FROM @xml.nodes('Designations/Designation') AS T(c)
  186. -- --UNION ALL
  187. -- --SELECT
  188. -- -- T.c.value('(UniqueID)[1]', 'varchar(500)') AS 'UniqueID',
  189. -- -- STUFF((
  190. -- -- SELECT ', ' + ISNULL(Name.value('(Name1)[8]', 'varchar(100)'), '') +
  191. -- -- ' ' + ISNULL(Name.value('(Name2)[8]', 'varchar(100)'), '') +
  192. -- -- ' ' + ISNULL(Name.value('(Name6)[8]', 'varchar(100)'), '')
  193. -- -- FROM T.c.nodes('Names/Name[NameType="Alias"]') AS Name(Name)
  194. -- -- FOR XML PATH(''), TYPE
  195. -- -- ).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_FullName1'
  196. -- --FROM @xml.nodes('Designations/Designation') AS T(c)
  197. -- ) X
  198. --SELECT * FROM #TEMPINDVALIASNAME
  199. --RETURN
  200. --######################END OF INDIVIDUAL LIST-- ###################################
  201. -- ENTITY
  202. --########## BEGINING OF ENTITY ###############################################
  203. --commented out
  204. SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID'
  205. ,T.c.value('OFSIGroupID[1]', 'varchar(500)') AS 'OFSIGroupID'
  206. ,T.c.value('UNReferenceNumber[1]', 'varchar(500)') AS 'UNReferenceNumber'
  207. , STUFF((
  208. SELECT ', ' + ISNULL(Name.value('(Name6)[1]', 'varchar(100)'), '')
  209. FROM T.c.nodes('Names/Name[NameType="Primary Name"]') AS Names(Name)
  210. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'FullName'
  211. , STUFF((
  212. SELECT ', ' + NonLatinName.value('(NameNonLatinScript)[1]', 'nvarchar(MAX)')
  213. FROM T.c.nodes('NonLatinNames/NonLatinName') AS NonLatinNames(NonLatinName)
  214. FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'NonLatinNames'
  215. ,T.c.value('RegimeName[1]', 'varchar(500)') AS 'RegimeName'
  216. ,'UN' AS 'from_file'
  217. ,'I' AS 'indEnt'
  218. ,'' AS 'OTHERFIELDS'
  219. ,T.c.value('IndividualEntityShip[1]', 'varchar(500)') AS 'IndividualEntityShip'
  220. ,T.c.value('DesignationSource[1]', 'varchar(500)') AS 'DesignationSource'
  221. ,T.c.value('SanctionsImposed[1]', 'varchar(500)') AS 'SanctionsImposed'
  222. , STUFF((
  223. SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') +
  224. ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') +
  225. ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') +
  226. ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') +
  227. ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') +
  228. ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') +
  229. ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') +
  230. ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '')
  231. FROM T.c.nodes('Addresses/Address[1]') AS Addresses(Address)
  232. FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'AddressLines'
  233. ,STUFF((
  234. SELECT ', ' + PhoneNumber.value('(PhoneNumber)[1]', 'nvarchar(MAX)'),'' +
  235. ', ' + PhoneNumber.value('(PhoneNumber)[2]', 'nvarchar(MAX)'),'' +
  236. ', ' + PhoneNumber.value('(PhoneNumber)[3]', 'nvarchar(MAX)'),'' +
  237. ', ' + PhoneNumber.value('(PhoneNumber)[4]', 'nvarchar(MAX)'),'' +
  238. ', ' + PhoneNumber.value('(PhoneNumber)[5]', 'nvarchar(MAX)'),'' +
  239. ', ' + PhoneNumber.value('(PhoneNumber)[6]', 'nvarchar(MAX)'),''
  240. FROM T.c.nodes('PhoneNumbers') AS PhoneNumbers(PhoneNumber)
  241. FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'PhoneNumber'
  242. ,STUFF((
  243. SELECT ', ' + EmailAddress.value('(EmailAddress)[1]', 'nvarchar(MAX)')
  244. FROM T.c.nodes('EmailAddresses') AS EmailAddresses(EmailAddress)
  245. FOR XML PATH(''), TYPE).value('.', 'nvarchar(MAX)'), 1, 2, '') AS 'EmailAddress'
  246. ,T.c.value('OtherInformation[1]', 'varchar(MAX)') AS 'Remarks'
  247. ,T.c.value('DateDesignated[1]', 'varchar(MAX)') AS 'DateDesignated'
  248. ,T.c.value('LastUpdated[1]', 'varchar(500)') AS 'LastUpdated'
  249. INTO #TEMPENTITYLIST
  250. FROM @xml.nodes('Designations/Designation') T(c)
  251. --SELECT * FROM #TEMPENTITYLIST
  252. --SELECT *
  253. --INTO #TEMPENTITYNAME
  254. --FROM (
  255. -- SELECT T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID'
  256. -- ,N.c.value('(Name6)[1]', 'varchar(100)') AS 'Alias_FullName2'
  257. -- , STUFF((
  258. -- SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') +
  259. -- ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') +
  260. -- ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') +
  261. -- ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') +
  262. -- ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') +
  263. -- ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') +
  264. -- ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') +
  265. -- ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '')
  266. -- FROM T.c.nodes('Addresses/Address') AS Addresses(Address)
  267. -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_AddressLines2'
  268. -- FROM @xml.nodes('Designations/Designation') T(c)
  269. -- CROSS APPLY T.c.nodes('Names/Name[NameType="Alias"]') AS N(c)
  270. --UNION ALL
  271. --SELECT
  272. -- T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID',
  273. -- N.c.value('(Name6)[1]', 'varchar(100)') AS 'Alias_FullName2',
  274. -- STUFF((
  275. -- SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') +
  276. -- ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') +
  277. -- ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') +
  278. -- ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') +
  279. -- ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') +
  280. -- ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') +
  281. -- ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') +
  282. -- ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '')
  283. -- FROM T.c.nodes('Addresses/Address[2]') AS Addresses(Address)
  284. -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_AddressLines2'
  285. --FROM @xml.nodes('Designations/Designation') AS T(c)
  286. --CROSS APPLY T.c.nodes('Names/Name[NameType="Alias"]') AS N(c)
  287. --UNION ALL
  288. --SELECT
  289. -- T.c.value('UniqueID[1]', 'varchar(500)') AS 'UniqueID',
  290. -- N.c.value('(Name6)[1]', 'varchar(100)') AS 'Alias_FullName2',
  291. -- STUFF((
  292. -- SELECT ', ' + ISNULL(Address.value('(AddressLine1)[1]', 'varchar(100)'), '') +
  293. -- ' ' + ISNULL(Address.value('(AddressLine2)[1]', 'varchar(100)'), '') +
  294. -- ' ' + ISNULL(Address.value('(AddressLine3)[1]', 'varchar(100)'), '') +
  295. -- ' ' + ISNULL(Address.value('(AddressLine4)[1]', 'varchar(100)'), '') +
  296. -- ' ' + ISNULL(Address.value('(AddressLine5)[1]', 'varchar(100)'), '') +
  297. -- ' ' + ISNULL(Address.value('(AddressLine6)[1]', 'varchar(100)'), '') +
  298. -- ' ' + ISNULL(Address.value('(AddressPostalCode)[1]', 'varchar(100)'), '') +
  299. -- ' ' + ISNULL(Address.value('(AddressCountry)[1]', 'varchar(100)'), '')
  300. -- FROM T.c.nodes('Addresses/Address[3]') AS Addresses(Address)
  301. -- FOR XML PATH(''), TYPE).value('.', 'varchar(MAX)'), 1, 2, '') AS 'Alias_AddressLines2'
  302. --FROM @xml.nodes('Designations/Designation') AS T(c)
  303. --CROSS APPLY T.c.nodes('Names/Name[NameType="Alias"]') AS N(c)
  304. --) x
  305. --SELECT * FROM #TEMPENTITYLIST
  306. --SELECT * FROM #TEMPENTITYNAME
  307. --return
  308. --select * from blacklist where dataSource='UNSCR'
  309. --############# INSERTING DATA ON BLACK LIST ############################################
  310. DELETE
  311. FROM blacklist
  312. --WHERE ENTNUM IN (SELECT DATAID FROM #TEMPUNSCRLIST)
  313. WHERE dataSource = 'UK_Saction_List'
  314. AND sourceEntNum = @source
  315. --DELETE FROM blacklistHISTORY
  316. --WHERE ENTNUM IN (SELECT DATAID FROM #TEMPUNSCRLIST)
  317. --AND dataSource='UNSCR'
  318. INSERT INTO blacklist (
  319. ofacKey
  320. ,entNum
  321. ,name
  322. ,vesselType
  323. ,address
  324. ,city
  325. ,zip
  326. ,country
  327. ,remarks
  328. ,sortOrder
  329. ,fromFile
  330. ,dataSource
  331. ,indEnt
  332. ,sourceEntNum
  333. )
  334. SELECT dataSource + '' + CAST(entNum AS VARCHAR)
  335. ,entNum
  336. ,[NAME]
  337. ,[vesselType]
  338. ,address
  339. ,city
  340. ,zip
  341. ,country
  342. ,remarks
  343. ,[sortOrder]
  344. ,fromFile
  345. ,[dataSource]
  346. ,indEnt
  347. ,sourceEntNum
  348. FROM (
  349. SELECT entNum = UniqueID
  350. ,[NAME] = FullName
  351. ,[vesselType] = 'sdn'
  352. ,address = NULL
  353. ,city = NULL
  354. ,zip = NULL
  355. ,country = NULL
  356. ,remarks = ISNULL(OFSIGroupID, '') + '/' + ' Designated Date: ' + ISNULL(REPLACE(DateDesignated, 'T00:00:00', ','), '') +
  357. ' Place Of Birth: ' + ISNULL(NULLIF(BirthTown + ', ' + BirthCountry, ', '), '') +
  358. ' Date of birth: ' + ISNULL(REPLACE(DOBs, 'T00:00:00', ','), '') +
  359. ' Title: ' + ISNULL(Title, '') +
  360. ' Nationality: ' + ISNULL(NATIONALITY, '') +
  361. ' Gender: ' + ISNULL(Gender, '') +
  362. ' Non Latin Name: ' + ISNULL(NonLatinName, '') +
  363. ' RegimeName: ' + ISNULL(RegimeName, '') +
  364. ' Position: ' + ISNULL(Position, '') +
  365. ' SanctionsImposed: ' + ISNULL(SanctionsImposed, '') +
  366. ' PassportNumber: ' + ISNULL(PassportNumber, '') +
  367. ' PassportAdditionalInformation: ' + ISNULL(PassportAdditionalInformation, '') +
  368. ' NID Number: ' + ISNULL(NID_Num, '') +
  369. ' NID Info: ' + ISNULL(NID_Info, '') +
  370. ' Remarks: ' + ISNULL(REMARKS, '') +
  371. ' UNList Type: ' + ISNULL(IndividualEntityShip, '') +
  372. ' Last Update date: ' + ISNULL(REPLACE(LastUpdated, 'T00:00:00', ','), '') +
  373. ' Reference No: ' + ISNULL(UNReferenceNumber, '') +
  374. ' Designation Source: ' + ISNULL(DesignationSource, '') +
  375. ' Individual EntityShip: ' + ISNULL(IndividualEntityShip, '')
  376. ,[sortOrder] = 1
  377. ,fromFile = @xmlFileName
  378. ,[dataSource] = @dataSource
  379. ,indEnt = INDENT
  380. ,sourceEntNum = @source
  381. FROM #TEMPUNSCRLIST WITH (NOLOCK)
  382. -- UNION ALL
  383. -- SELECT UniqueID
  384. -- --,REPLACE(REPLACE(Alias_FullName1, '? ', ''), '?', '')
  385. -- ,Alias_FullName1
  386. -- ,'alt'
  387. -- ,NULL
  388. -- ,NULL
  389. -- ,NULL
  390. -- ,NULL
  391. -- ,NULL
  392. -- ,2
  393. -- ,@xmlFileName [fromFile]
  394. -- ,@dataSource [dataSource]
  395. -- ,'I'
  396. -- ,sourceEntNum = @source
  397. -- FROM #TEMPINDVALIASNAME
  398. -- WHERE Alias_FullName1 IS NOT NULL
  399. -- AND Alias_FullName1 IS NOT NULL
  400. ----ISNULL(REPLACE(REPLACE(Alias_FullName1, '? ', ''), '?', ''), 'B') <> 'B'
  401. UNION ALL
  402. SELECT UniqueID
  403. ,FullName
  404. ,'sdn' [vesselType]
  405. ,NULL
  406. ,NULL
  407. ,NULL
  408. ,NULL
  409. ,ISNULL(OFSIGroupID, '') +
  410. ' Date Designated: ' + ISNULL(REPLACE(DateDesignated, 'T00:00:00', ','), '') +
  411. ' Non Latin Names: ' + ISNULL(NonLatinNames, '') +
  412. ' Regime Name: ' + ISNULL(RegimeName, '') +
  413. ' Individual EntityShip: ' + ISNULL(IndividualEntityShip, '') +
  414. ' Designation Source: ' + ISNULL(DesignationSource, '') +
  415. ' Sanctions Imposed: ' + ISNULL(SanctionsImposed, '') +
  416. ' Comments: ' + ISNULL(Remarks, '') +
  417. ' Address: ' + ISNULL(NULLIF(AddressLines + ', ' + '', ', '), '') +
  418. --' Address Postal Code: ' + ISNULL(AddressPostalCode, '') +
  419. ' Last updated date: ' + ISNULL(REPLACE(LastUpdated, 'T00:00:00', ','), '') +
  420. ' Reference No: ' + ISNULL(UNReferenceNumber, '') [remarks]
  421. ,1 [sortOrder]
  422. ,@xmlFileName [fromFile]
  423. ,@dataSource [dataSource]
  424. ,INDENT
  425. ,sourceEntNum = @source
  426. FROM #TEMPENTITYLIST WITH (NOLOCK)
  427. --UNION ALL
  428. --SELECT UniqueID
  429. -- ,Alias_FullName2
  430. -- ,'alt'
  431. -- ,NULL
  432. -- ,NULL
  433. -- ,NULL
  434. -- ,NULL
  435. -- ,NULL
  436. -- ,2
  437. -- ,@xmlFileName [fromFile]
  438. -- ,@dataSource [dataSource]
  439. -- ,'E'
  440. -- ,sourceEntNum = @source
  441. --FROM #TEMPENTITYNAME
  442. --WHERE Alias_FullName2 IS NOT NULL
  443. --UNION ALL
  444. --SELECT UniqueID
  445. -- ,NULL
  446. -- ,'add'
  447. -- ,Alias_AddressLines2
  448. -- ,NULL
  449. -- ,NULL--Alias_AddressPostalCode2
  450. -- ,NULL--Alias_AddressCountry2
  451. -- ,NULL
  452. -- ,3
  453. -- ,@xmlFileName [fromFile]
  454. -- ,@dataSource [dataSource]
  455. -- ,'E'
  456. -- ,sourceEntNum = @source
  457. --FROM #TEMPENTITYNAME
  458. --WHERE --(
  459. -- Alias_AddressLines2 IS NOT NULL
  460. -- --OR Alias_AddressPostalCode2 IS NOT NULL
  461. -- --OR Alias_AddressCountry2 IS NOT NULL
  462. -- --)
  463. ) x
  464. DECLARE @sdnCount INT
  465. SELECT @sdnCount = COUNT(*)
  466. FROM #TEMPUNSCRLIST
  467. --SELECT @sdnCount = @sdnCount + COUNT(*)
  468. --FROM #TEMPENTITYNAME
  469. INSERT INTO blacklistLog (
  470. totalRecord
  471. ,dataSource
  472. ,createdBy
  473. ,createdDate
  474. ,ofacDate
  475. )
  476. SELECT @sdnCount
  477. ,@dataSource + ':' + @source
  478. ,@user
  479. ,GETDATE()
  480. ,CAST(LEFT(@ofacDate, 10) AS DATE)
  481. DROP TABLE #TEMPUNSCRLIST
  482. --DROP TABLE #TEMPINDVALIASNAME
  483. --DROP TABLE #TEMPENTITYNAME
  484. DROP TABLE #TEMPENTITYLIST
  485. MERGE blackListHistory AS blh
  486. USING (
  487. SELECT rowId
  488. ,ofacKey
  489. ,entNum
  490. ,name
  491. ,vesselType
  492. ,address
  493. ,city
  494. ,STATE
  495. ,zip
  496. ,country
  497. ,remarks
  498. ,sortOrder
  499. ,fromFile
  500. ,dataSource
  501. ,indEnt
  502. FROM blacklist WITH (NOLOCK)
  503. WHERE dataSource = 'UK_Saction_List' /* @dataSource*/
  504. ) AS bl
  505. ON ISNULL(blh.ofacKey, '') = ISNULL(bl.ofacKey, '')
  506. AND ISNULL(blh.entNum, '') = ISNULL(bl.entNum, '')
  507. AND ISNULL(blh.name, '') = ISNULL(bl.name, '')
  508. AND ISNULL(blh.vesselType, '') = ISNULL(bl.vesselType, '')
  509. AND ISNULL(blh.address, '') = ISNULL(bl.address, '')
  510. AND ISNULL(blh.city, '') = ISNULL(bl.city, '')
  511. AND ISNULL(blh.STATE, '') = ISNULL(bl.STATE, '')
  512. AND ISNULL(blh.zip, '') = ISNULL(bl.zip, '')
  513. AND ISNULL(blh.country, '') = ISNULL(bl.country, '')
  514. AND ISNULL(blh.remarks, '') = ISNULL(bl.remarks, '')
  515. AND ISNULL(blh.sortOrder, '') = ISNULL(bl.sortOrder, '')
  516. AND ISNULL(blh.fromFile, '') = ISNULL(bl.fromFile, '')
  517. AND ISNULL(blh.dataSource, '') = ISNULL(bl.dataSource, '')
  518. AND ISNULL(blh.indEnt, '') = ISNULL(bl.indEnt, '')
  519. AND bl.dataSource = 'UK_Saction_List' --@dataSource
  520. AND sourceEntNum = @source
  521. WHEN NOT MATCHED
  522. THEN
  523. INSERT (
  524. blackListId
  525. ,ofacKey
  526. ,entNum
  527. ,name
  528. ,vesselType
  529. ,address
  530. ,city
  531. ,STATE
  532. ,zip
  533. ,country
  534. ,remarks
  535. ,sortOrder
  536. ,fromFile
  537. ,dataSource
  538. ,indEnt
  539. )
  540. VALUES (
  541. bl.rowId
  542. ,bl.ofacKey
  543. ,bl.entNum
  544. ,bl.name
  545. ,bl.vesselType
  546. ,bl.address
  547. ,bl.city
  548. ,bl.STATE
  549. ,bl.zip
  550. ,bl.country
  551. ,bl.remarks
  552. ,bl.sortOrder
  553. ,bl.fromFile
  554. ,bl.dataSource
  555. ,bl.indEnt
  556. );
  557. --INSERT INTO blacklistHistory (blackListId,entNum,name,vesselType,address,city,zip,country,remarks,sortOrder,fromFile,dataSource,indEnt)
  558. --SELECT rowId,entNum,name,vesselType,address,city,zip,country,remarks,sortOrder,fromFile,dataSource,indEnt
  559. --FROM blacklist WITH(NOLOCK) WHERE dataSource='UNSCR'
  560. IF @@TRANCOUNT > 0
  561. COMMIT TRANSACTION
  562. SELECT 0 error_code
  563. ,'Sanctions List Data imported successfully' mes
  564. ,NULL AS id
  565. --EXEC PROC_UPDATE_METAPHONE
  566. END
  567. END
  568. --- ENTITY CLOSE
  569. END TRY
  570. BEGIN CATCH
  571. IF @@TRANCOUNT > 0
  572. ROLLBACK TRANSACTION
  573. SELECT 1 error_code
  574. ,ERROR_MESSAGE() mes
  575. ,NULL AS id
  576. END CATCH