ShipDynamicsMapper.xml 23 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355
  1. <?xml version="1.0" encoding="UTF-8"?>
  2. <!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
  3. <mapper namespace="com.steerinfo.dil.mapper.ShipDynamicsMapper">
  4. <!-- 获取船舶动态表数据 -->
  5. <select id="selectAll" resultType="java.util.Map" parameterType="java.util.Map">
  6. SELECT * FROM (
  7. select DISTINCT
  8. db.BATCH_ID "batchId",
  9. DBI2.BATCH_INFACOTRY_ID "batchInfacoryId",
  10. db.result_foreign_ship_name "shipName",
  11. rm.material_name "materialName",
  12. adn.NOTICE_DELIVERY_TIME "dateOfLoans",
  13. adn.RESULT_NUMBER_OF_LOANS "numberOfLoans",
  14. rp.port_name "portName",
  15. wgm.gm_tonnage "tonnage",
  16. rc.capacity_number "capacity",
  17. tlsr.RESULT_ACTUAL_INSTALLATIONS "capacityNumber",
  18. tlsr.RESULT_OUT_PORT_TIME "outPortTime",
  19. tlsr.RESULT_ARRIVAL_PORT_TIME "dgsj",
  20. tsl.LOCATION_STATUS "locationStatus",
  21. tsl.LOCATION_VALUE "locationValue",
  22. tsl.LOCATION_ROUTE_TIME,
  23. NVL(ADN.RESULT_MEMO,'块矿') "materialTypeName",
  24. RMT.MATERIAL_TYPE_ID "materialTypeId",
  25. OSI.INSTRUCTIONS_STATUS "instructionStatus"
  26. from AMSSHIP_DELIVERY_NOTICE adn
  27. LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
  28. LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
  29. JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
  30. join rms_material rm on db.material_id=rm.material_id
  31. left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
  32. left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
  33. left join TMSSHIP_LOAD_SHIP_RESULT tlsr on DBI2.BATCH_INFACOTRY_ID=tlsr.batch_id
  34. left join tmsship_total_result ttr on ttr.result_id=tlsr.TOTAL_RESULT_ID
  35. left join omsship_instructions_capacity oic on ttr.order_id=oic.instructions_capacity_id
  36. left join OMSSHIP_SHIPMENT_INSTRUCTIONS OSI ON OSI.SHIPMENT_INSTRUCTIONS_ID=oic.INSTRUCTIONS_ID
  37. left join rms_capacity rc on oic.capacity_id=rc.capacity_id
  38. left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
  39. left join (select * from tmsship_ship_location t where t.location_id in
  40. (SELECT
  41. t.location_id
  42. FROM
  43. (
  44. SELECT
  45. t.location_id,
  46. t.total_result_id,
  47. t.location_route_time,
  48. ROW_NUMBER () OVER (
  49. PARTITION BY t.total_result_id
  50. ORDER BY t.location_route_time DESC
  51. ) AS rn
  52. FROM
  53. tmsship_ship_location t
  54. ) t
  55. WHERE
  56. rn = 1)) tsl on tsl.total_result_id=ttr.result_id
  57. where ttr.ship_status = 0 and tsl.LOCATION_STATUS is not null and tlsr.DELETED=0
  58. and adn.DELETED=0 and oic.DELETED=0
  59. union all
  60. select DISTINCT
  61. db.BATCH_ID "batchId",
  62. DBI2.BATCH_INFACOTRY_ID "batchInfacoryId",
  63. db.result_foreign_ship_name "shipName",
  64. rm.material_name "materialName",
  65. adn.NOTICE_DELIVERY_TIME "dateOfLoans",
  66. adn.RESULT_NUMBER_OF_LOANS "numberOfLoans",
  67. rp.port_name "portName",
  68. wgm.gm_tonnage "tonnage",
  69. null "capacity",
  70. 0 "capacityNumber",
  71. null "outPortTime",
  72. null "dgsj",
  73. null "locationStatus",
  74. null "locationValue",
  75. null,
  76. null "materialTypeName",
  77. null "materialTypeId",
  78. null "instructionStatus"
  79. from AMSSHIP_DELIVERY_NOTICE adn
  80. LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
  81. LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
  82. JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
  83. join rms_material rm on db.material_id=rm.material_id
  84. left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
  85. left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
  86. left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
  87. where adn.DELETED=0 and wgm.DELETED=0 and wgm.gm_tonnage>0
  88. and DBI2.BATCH_INFACOTRY_ID not in(
  89. select DISTINCT
  90. DBI2.BATCH_INFACOTRY_ID "batchInfacoryId"
  91. from AMSSHIP_DELIVERY_NOTICE adn
  92. LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
  93. LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
  94. JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
  95. join rms_material rm on db.material_id=rm.material_id
  96. left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
  97. left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
  98. left join TMSSHIP_LOAD_SHIP_RESULT tlsr on DBI2.BATCH_INFACOTRY_ID=tlsr.batch_id
  99. left join tmsship_total_result ttr on ttr.result_id=tlsr.TOTAL_RESULT_ID
  100. left join omsship_instructions_capacity oic on ttr.order_id=oic.instructions_capacity_id
  101. left join OMSSHIP_SHIPMENT_INSTRUCTIONS OSI ON OSI.SHIPMENT_INSTRUCTIONS_ID=oic.INSTRUCTIONS_ID
  102. left join rms_capacity rc on oic.capacity_id=rc.capacity_id
  103. left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
  104. left join (select * from tmsship_ship_location t where t.location_id in
  105. (SELECT
  106. t.location_id
  107. FROM
  108. (
  109. SELECT
  110. t.location_id,
  111. t.total_result_id,
  112. t.location_route_time,
  113. ROW_NUMBER () OVER (
  114. PARTITION BY t.total_result_id
  115. ORDER BY t.location_route_time DESC
  116. ) AS rn
  117. FROM
  118. tmsship_ship_location t
  119. ) t
  120. WHERE
  121. rn = 1)) tsl on tsl.total_result_id=ttr.result_id
  122. where ttr.ship_status = 0 and tsl.LOCATION_STATUS is not null and tlsr.DELETED=0
  123. and adn.DELETED=0 and oic.DELETED=0
  124. )
  125. )
  126. Order By "materialTypeName","batchId","batchInfacoryId" DESC
  127. </select>
  128. <select id="selectByshipName" resultType="java.util.Map" parameterType="java.util.Map">
  129. select sd.GM_TONNAGE as "tonnage",
  130. sd.RESULT_DATE_OF_LOANS as "dateOfLoans",
  131. sd.RESULT_NUMBER_OF_LOANS as "numberOfLoans",
  132. sd.PORT_NAME as "portName",
  133. sd.CAPACITY_NUMBER as "capacity",
  134. sd.RESULT_ACTUAL_INSTALLATIONS as "capacityNumber",
  135. sd.RESULT_OUT_PORT_TIME as "outPortTime",
  136. sd.LOCATION_VALUE as "locationValue",
  137. sd.LOCATION_STATUS as "locationStatus"
  138. from SHIP_DYNAMICS sd where sd.RESULT_FOREIGN_SHIP_NAME=#{shipName} and sd.MATERIAL_NAME=#{materialName} and sd.LOCATION_STATUS is not null
  139. </select>
  140. <select id="getLoadData" resultType="java.util.Map">
  141. select COUNT(TLT.RESULT_ID) as "num",
  142. DB.RESULT_FOREIGN_SHIP_NAME "resultForeignShipName",
  143. rm.MATERIAL_NAME "materialName",
  144. '港口装车数据' "dataType"
  145. from TMSTRAIN_LOADING_TEMP TLT
  146. LEFT JOIN WMSH_OUTBOUND_RESULT WOR
  147. ON WOR.RESULT_ID = TLT.OUTBOUNT_ID
  148. LEFT JOIN DIL_BATCH DB
  149. ON WOR.BATCH_ID = DB.BATCH_ID
  150. LEFT JOIN RMS_MATERIAL RM
  151. ON DB.MATERIAL_ID = RM.MATERIAL_ID
  152. <where>
  153. <if test="input !=null and input.toString()!=''">
  154. DB.RESULT_FOREIGN_SHIP_NAME || rm.MATERIAL_NAME like concat('%',concat(#{input},'%'))
  155. </if>
  156. <if test="oneDate != null">
  157. and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= WOR.INSERT_TIME
  158. </if>
  159. <if test="startDate != null">
  160. and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= WOR.INSERT_TIME
  161. and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= WOR.INSERT_TIME
  162. </if>
  163. </where>
  164. GROUP BY rm.MATERIAL_NAME,DB.RESULT_FOREIGN_SHIP_NAME
  165. ORDER BY rm.MATERIAL_NAME
  166. </select>
  167. <select id="getUnloadData" resultType="java.util.Map">
  168. --卸船明细
  169. SELECT
  170. ( CASE WHEN TTR.SHIP_STATUS = 1 THEN '已卸船数' ELSE '待卸船数' END ) AS "status",
  171. COUNT(TTR.SHIP_STATUS) AS "num",
  172. '港口卸船数据' "dataType"
  173. FROM
  174. TMSSHIP_TOTAL_RESULT TTR
  175. LEFT JOIN TMSSHIP_UNLOAD_SHIP_RESULT TUSR ON TUSR.TOTAL_RESULT_ID = TTR.RESULT_ID
  176. LEFT JOIN OMSSHIP_INSTRUCTIONS_CAPACITY OIC ON TTR.ORDER_ID = OIC.INSTRUCTIONS_CAPACITY_ID
  177. LEFT JOIN RMS_CAPACITY RC ON OIC.CAPACITY_ID = RC.CAPACITY_ID
  178. WHERE TUSR.DELETED=0 and TTR.SHIP_STATUS = 1
  179. <if test="oneDate != null">
  180. and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= TUSR.INSERT_TIME
  181. </if>
  182. <if test="startDate != null">
  183. and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= TUSR.INSERT_TIME
  184. and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= TUSR.INSERT_TIME
  185. </if>
  186. GROUP BY TTR.SHIP_STATUS
  187. </select>
  188. <select id="getLocationData" resultType="java.util.Map">
  189. select count(LOCATION_ID) "num",DECODE(LOCATION_VALUE, '等卸', '待卸船数','在卸','在卸船数') as "status"
  190. from TMSSHIP_SHIP_LOCATION
  191. where LOCATION_VALUE='等卸' or LOCATION_VALUE='待卸'
  192. <if test="oneDate != null">
  193. and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= UPDATE_TIME
  194. </if>
  195. <if test="startDate != null">
  196. and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= UPDATE_TIME
  197. and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= UPDATE_TIME
  198. </if>
  199. GROUP BY LOCATION_VALUE
  200. </select>
  201. <select id="getDownShipDynamaics" resultType="java.util.Map">
  202. --下游港口船舶动态表
  203. SELECT
  204. DISTINCT
  205. OSI.SHIPMENT_INSTRUCTIONS_ID "instructionsId",
  206. OIC.INSTRUCTIONS_CAPACITY_ID "instructionsCapacityId",
  207. ADN.PORT_ID "adnPortId",
  208. WGM.GM_ID "gmId",
  209. WGM.PORT_ID "portId",
  210. WGM.BATCH_ID "batchId",
  211. RP.PORT_NAME "portName",
  212. RM.MATERIAL_NAME || '(' || DB.RESULT_FOREIGN_SHIP_NAME || ')' || ADN.RESULT_NUMBER_OF_LOANS || '吨,' || TO_CHAR(ADN.NOTICE_DELIVERY_TIME,'YYYY-MM-DD') ||'放货'
  213. ||
  214. (case
  215. when OSI.HANDOVER_MODE IS NULL
  216. then ''
  217. else '(二程:' || OSI.HANDOVER_MODE || ')'
  218. end) "productName",
  219. WGM.GM_TONNAGE "gmTonnage",
  220. (case
  221. when TWQR.IS_NEED_ASSEMBLE = '是'
  222. then RC.CAPACITY_NUMBER ||'(拼装)'
  223. else RC.CAPACITY_NUMBER
  224. end)
  225. "capacityNumber",
  226. oic.INSTRUCTION_PLANNED_LOADING "planLoadTon",
  227. oic.INSTRUCTIONS_SHIP_POSITION "position",
  228. TLSR.RESULT_ACTUAL_INSTALLATIONS "actualLoadTon",
  229. oic.SHIP_DYNAMIC "shipDynamic",
  230. oic.LOAD_DETAILS "loadDetails",
  231. ADN.NOTICE_DELIVERY_TIME "noticeDeliveryTime"
  232. from AMSSHIP_DELIVERY_NOTICE ADN
  233. LEFT JOIN RMS_PORT RP
  234. ON RP.PORT_ID = ADN.PORT_ID
  235. LEFT JOIN OMSSHIP_SHIPMENT_INSTRUCTIONS OSI
  236. ON OSI.BATCH_ID = ADN.BATCH_ID
  237. LEFT JOIN OMSSHIP_INSTRUCTIONS_CAPACITY OIC
  238. ON OIC.INSTRUCTIONS_ID = OSI.SHIPMENT_INSTRUCTIONS_ID
  239. LEFT JOIN RMS_CAPACITY RC
  240. ON RC.CAPACITY_ID =OIC.CAPACITY_ID
  241. LEFT JOIN DIL_BATCH_INFACOTRY DBI
  242. ON DBI.BATCH_INFACOTRY_ID = ADN.BATCH_ID
  243. LEFT JOIN DIL_BATCH DB
  244. ON DB.BATCH_ID = DBI.BATCH_ID
  245. left join RMS_MATERIAL RM
  246. ON RM.MATERIAL_ID = DB.MATERIAL_ID
  247. LEFT JOIN WMSH_GRID_MATERIAL WGM
  248. ON WGM.BATCH_ID = DB.BATCH_ID AND ADN.PORT_ID=WGM.PORT_ID
  249. LEFT JOIN TMSSHIP_TOTAL_RESULT TTR
  250. ON OIC.INSTRUCTIONS_CAPACITY_ID=TTR.ORDER_ID
  251. LEFT JOIN TMSSHIP_WATER_QUALITY_RESULT TWQR
  252. ON TWQR.TOTAL_RESULT_ID=TTR.RESULT_ID
  253. LEFT JOIN TMSSHIP_LOAD_SHIP_RESULT TLSR
  254. ON TLSR.TOTAL_RESULT_ID=TTR.RESULT_ID
  255. <where>
  256. ADN.DELETED=0
  257. <if test="input !=null and input.toString()!=''">
  258. and RC.CAPACITY_NUMBER || RP.PORT_NAME || DB.RESULT_FOREIGN_SHIP_NAME || rm.MATERIAL_NAME like concat('%',concat(#{input},'%'))
  259. </if>
  260. <if test="oneDate != null">
  261. and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= ADN.NOTICE_DELIVERY_TIME
  262. </if>
  263. <if test="startDate != null">
  264. and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= ADN.NOTICE_DELIVERY_TIME
  265. and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= ADN.NOTICE_DELIVERY_TIME
  266. </if>
  267. </where>
  268. ORDER BY RP.PORT_NAME,ADN.NOTICE_DELIVERY_TIME DESC
  269. </select>
  270. <select id="getPleaseData" resultType="java.util.Map">
  271. select sum(RESULT_APPROVE_NUMBER) "approveSum",sum(RESULT_SURPLUS_NUMBER) "surplusSum" from TMSTRAIN_PLEASE_RESULT
  272. where DELETED=0
  273. <if test="oneDate != null">
  274. and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= RESULT_DATE
  275. </if>
  276. <if test="startDate != null">
  277. and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') &lt;= RESULT_DATE
  278. and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= RESULT_DATE
  279. </if>
  280. </select>
  281. <select id="getRealNumberMonth" resultType="java.math.BigDecimal">
  282. select count(TLT.RESULT_ID) from TMSTRAIN_LOADING_TEMP TLT,WMSH_OUTBOUND_RESULT WOR
  283. where TLT.OUTBOUNT_ID=WOR.RESULT_ID
  284. AND #{monthDate} = TO_CHAR(WOR.INSERT_TIME,'YYYY-MM')
  285. </select>
  286. <select id="selectAllUnload" resultType="java.util.Map">
  287. SELECT *
  288. FROM (
  289. select DISTINCT
  290. db.BATCH_ID "batchId",
  291. DBI2.BATCH_INFACOTRY_ID "batchInfacoryId",
  292. db.result_foreign_ship_name "shipName",
  293. rm.material_name "materialName",
  294. RMT.MATERIAL_TYPE_NAME "materialTypeName",
  295. adn.NOTICE_DELIVERY_TIME "dateOfLoans",
  296. adn.RESULT_NUMBER_OF_LOANS "numberOfLoans",
  297. rp.port_name "portName",
  298. wgm.gm_tonnage "tonnage"
  299. from AMSSHIP_DELIVERY_NOTICE adn
  300. LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
  301. LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
  302. JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
  303. join rms_material rm on db.material_id=rm.material_id
  304. left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
  305. left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
  306. left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
  307. where adn.DELETED=0 and wgm.DELETED=0 and wgm.gm_tonnage>0
  308. and DBI2.BATCH_INFACOTRY_ID not in(
  309. select DISTINCT
  310. DBI2.BATCH_INFACOTRY_ID "batchInfacoryId"
  311. from AMSSHIP_DELIVERY_NOTICE adn
  312. LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
  313. LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
  314. JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
  315. join rms_material rm on db.material_id=rm.material_id
  316. left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
  317. left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
  318. left join TMSSHIP_LOAD_SHIP_RESULT tlsr on DBI2.BATCH_INFACOTRY_ID=tlsr.batch_id
  319. left join tmsship_total_result ttr on ttr.result_id=tlsr.TOTAL_RESULT_ID
  320. left join omsship_instructions_capacity oic on ttr.order_id=oic.instructions_capacity_id
  321. left join OMSSHIP_SHIPMENT_INSTRUCTIONS OSI ON OSI.SHIPMENT_INSTRUCTIONS_ID=oic.INSTRUCTIONS_ID
  322. left join rms_capacity rc on oic.capacity_id=rc.capacity_id
  323. left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
  324. left join (select * from tmsship_ship_location t where t.location_id in
  325. (SELECT
  326. t.location_id
  327. FROM
  328. (
  329. SELECT
  330. t.location_id,
  331. t.total_result_id,
  332. t.location_route_time,
  333. ROW_NUMBER () OVER (
  334. PARTITION BY t.total_result_id
  335. ORDER BY t.location_route_time DESC
  336. ) AS rn
  337. FROM
  338. tmsship_ship_location t
  339. ) t
  340. WHERE
  341. rn = 1)) tsl on tsl.total_result_id=ttr.result_id
  342. where ttr.ship_status = 0 and tsl.LOCATION_STATUS is not null and tlsr.DELETED=0
  343. and adn.DELETED=0 and oic.DELETED=0
  344. )
  345. )
  346. <if test="con!=null and con!=''.toString()">
  347. WHERE instr( "materialName", #{con} ) > 0 OR instr( "shipName", #{con} ) > 0
  348. </if>
  349. Order By "batchInfacoryId" DESC
  350. </select>
  351. </mapper>