123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355 |
- <?xml version="1.0" encoding="UTF-8"?>
- <!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
- <mapper namespace="com.steerinfo.dil.mapper.ShipDynamicsMapper">
- <!-- 获取船舶动态表数据 -->
- <select id="selectAll" resultType="java.util.Map" parameterType="java.util.Map">
- SELECT * FROM (
- select DISTINCT
- db.BATCH_ID "batchId",
- DBI2.BATCH_INFACOTRY_ID "batchInfacoryId",
- db.result_foreign_ship_name "shipName",
- rm.material_name "materialName",
- adn.NOTICE_DELIVERY_TIME "dateOfLoans",
- adn.RESULT_NUMBER_OF_LOANS "numberOfLoans",
- rp.port_name "portName",
- wgm.gm_tonnage "tonnage",
- rc.capacity_number "capacity",
- tlsr.RESULT_ACTUAL_INSTALLATIONS "capacityNumber",
- tlsr.RESULT_OUT_PORT_TIME "outPortTime",
- tlsr.RESULT_ARRIVAL_PORT_TIME "dgsj",
- tsl.LOCATION_STATUS "locationStatus",
- tsl.LOCATION_VALUE "locationValue",
- tsl.LOCATION_ROUTE_TIME,
- NVL(ADN.RESULT_MEMO,'块矿') "materialTypeName",
- RMT.MATERIAL_TYPE_ID "materialTypeId",
- OSI.INSTRUCTIONS_STATUS "instructionStatus"
- from AMSSHIP_DELIVERY_NOTICE adn
- LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
- LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
- JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
- join rms_material rm on db.material_id=rm.material_id
- left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
- left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
- left join TMSSHIP_LOAD_SHIP_RESULT tlsr on DBI2.BATCH_INFACOTRY_ID=tlsr.batch_id
- left join tmsship_total_result ttr on ttr.result_id=tlsr.TOTAL_RESULT_ID
- left join omsship_instructions_capacity oic on ttr.order_id=oic.instructions_capacity_id
- left join OMSSHIP_SHIPMENT_INSTRUCTIONS OSI ON OSI.SHIPMENT_INSTRUCTIONS_ID=oic.INSTRUCTIONS_ID
- left join rms_capacity rc on oic.capacity_id=rc.capacity_id
- left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
- left join (select * from tmsship_ship_location t where t.location_id in
- (SELECT
- t.location_id
- FROM
- (
- SELECT
- t.location_id,
- t.total_result_id,
- t.location_route_time,
- ROW_NUMBER () OVER (
- PARTITION BY t.total_result_id
- ORDER BY t.location_route_time DESC
- ) AS rn
- FROM
- tmsship_ship_location t
- ) t
- WHERE
- rn = 1)) tsl on tsl.total_result_id=ttr.result_id
- where ttr.ship_status = 0 and tsl.LOCATION_STATUS is not null and tlsr.DELETED=0
- and adn.DELETED=0 and oic.DELETED=0
- union all
- select DISTINCT
- db.BATCH_ID "batchId",
- DBI2.BATCH_INFACOTRY_ID "batchInfacoryId",
- db.result_foreign_ship_name "shipName",
- rm.material_name "materialName",
- adn.NOTICE_DELIVERY_TIME "dateOfLoans",
- adn.RESULT_NUMBER_OF_LOANS "numberOfLoans",
- rp.port_name "portName",
- wgm.gm_tonnage "tonnage",
- null "capacity",
- 0 "capacityNumber",
- null "outPortTime",
- null "dgsj",
- null "locationStatus",
- null "locationValue",
- null,
- null "materialTypeName",
- null "materialTypeId",
- null "instructionStatus"
- from AMSSHIP_DELIVERY_NOTICE adn
- LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
- LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
- JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
- join rms_material rm on db.material_id=rm.material_id
- left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
- left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
- left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
- where adn.DELETED=0 and wgm.DELETED=0 and wgm.gm_tonnage>0
- and DBI2.BATCH_INFACOTRY_ID not in(
- select DISTINCT
- DBI2.BATCH_INFACOTRY_ID "batchInfacoryId"
- from AMSSHIP_DELIVERY_NOTICE adn
- LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
- LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
- JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
- join rms_material rm on db.material_id=rm.material_id
- left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
- left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
- left join TMSSHIP_LOAD_SHIP_RESULT tlsr on DBI2.BATCH_INFACOTRY_ID=tlsr.batch_id
- left join tmsship_total_result ttr on ttr.result_id=tlsr.TOTAL_RESULT_ID
- left join omsship_instructions_capacity oic on ttr.order_id=oic.instructions_capacity_id
- left join OMSSHIP_SHIPMENT_INSTRUCTIONS OSI ON OSI.SHIPMENT_INSTRUCTIONS_ID=oic.INSTRUCTIONS_ID
- left join rms_capacity rc on oic.capacity_id=rc.capacity_id
- left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
- left join (select * from tmsship_ship_location t where t.location_id in
- (SELECT
- t.location_id
- FROM
- (
- SELECT
- t.location_id,
- t.total_result_id,
- t.location_route_time,
- ROW_NUMBER () OVER (
- PARTITION BY t.total_result_id
- ORDER BY t.location_route_time DESC
- ) AS rn
- FROM
- tmsship_ship_location t
- ) t
- WHERE
- rn = 1)) tsl on tsl.total_result_id=ttr.result_id
- where ttr.ship_status = 0 and tsl.LOCATION_STATUS is not null and tlsr.DELETED=0
- and adn.DELETED=0 and oic.DELETED=0
- )
- )
- Order By "materialTypeName","batchId","batchInfacoryId" DESC
- </select>
- <select id="selectByshipName" resultType="java.util.Map" parameterType="java.util.Map">
- select sd.GM_TONNAGE as "tonnage",
- sd.RESULT_DATE_OF_LOANS as "dateOfLoans",
- sd.RESULT_NUMBER_OF_LOANS as "numberOfLoans",
- sd.PORT_NAME as "portName",
- sd.CAPACITY_NUMBER as "capacity",
- sd.RESULT_ACTUAL_INSTALLATIONS as "capacityNumber",
- sd.RESULT_OUT_PORT_TIME as "outPortTime",
- sd.LOCATION_VALUE as "locationValue",
- sd.LOCATION_STATUS as "locationStatus"
- from SHIP_DYNAMICS sd where sd.RESULT_FOREIGN_SHIP_NAME=#{shipName} and sd.MATERIAL_NAME=#{materialName} and sd.LOCATION_STATUS is not null
- </select>
- <select id="getLoadData" resultType="java.util.Map">
- select COUNT(TLT.RESULT_ID) as "num",
- DB.RESULT_FOREIGN_SHIP_NAME "resultForeignShipName",
- rm.MATERIAL_NAME "materialName",
- '港口装车数据' "dataType"
- from TMSTRAIN_LOADING_TEMP TLT
- LEFT JOIN WMSH_OUTBOUND_RESULT WOR
- ON WOR.RESULT_ID = TLT.OUTBOUNT_ID
- LEFT JOIN DIL_BATCH DB
- ON WOR.BATCH_ID = DB.BATCH_ID
- LEFT JOIN RMS_MATERIAL RM
- ON DB.MATERIAL_ID = RM.MATERIAL_ID
- <where>
- <if test="input !=null and input.toString()!=''">
- DB.RESULT_FOREIGN_SHIP_NAME || rm.MATERIAL_NAME like concat('%',concat(#{input},'%'))
- </if>
- <if test="oneDate != null">
- and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') <= WOR.INSERT_TIME
- </if>
- <if test="startDate != null">
- and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') <= WOR.INSERT_TIME
- and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= WOR.INSERT_TIME
- </if>
- </where>
- GROUP BY rm.MATERIAL_NAME,DB.RESULT_FOREIGN_SHIP_NAME
- ORDER BY rm.MATERIAL_NAME
- </select>
- <select id="getUnloadData" resultType="java.util.Map">
- --卸船明细
- SELECT
- ( CASE WHEN TTR.SHIP_STATUS = 1 THEN '已卸船数' ELSE '待卸船数' END ) AS "status",
- COUNT(TTR.SHIP_STATUS) AS "num",
- '港口卸船数据' "dataType"
- FROM
- TMSSHIP_TOTAL_RESULT TTR
- LEFT JOIN TMSSHIP_UNLOAD_SHIP_RESULT TUSR ON TUSR.TOTAL_RESULT_ID = TTR.RESULT_ID
- LEFT JOIN OMSSHIP_INSTRUCTIONS_CAPACITY OIC ON TTR.ORDER_ID = OIC.INSTRUCTIONS_CAPACITY_ID
- LEFT JOIN RMS_CAPACITY RC ON OIC.CAPACITY_ID = RC.CAPACITY_ID
- WHERE TUSR.DELETED=0 and TTR.SHIP_STATUS = 1
- <if test="oneDate != null">
- and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') <= TUSR.INSERT_TIME
- </if>
- <if test="startDate != null">
- and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') <= TUSR.INSERT_TIME
- and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= TUSR.INSERT_TIME
- </if>
- GROUP BY TTR.SHIP_STATUS
- </select>
- <select id="getLocationData" resultType="java.util.Map">
- select count(LOCATION_ID) "num",DECODE(LOCATION_VALUE, '等卸', '待卸船数','在卸','在卸船数') as "status"
- from TMSSHIP_SHIP_LOCATION
- where LOCATION_VALUE='等卸' or LOCATION_VALUE='待卸'
- <if test="oneDate != null">
- and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') <= UPDATE_TIME
- </if>
- <if test="startDate != null">
- and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') <= UPDATE_TIME
- and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= UPDATE_TIME
- </if>
- GROUP BY LOCATION_VALUE
- </select>
- <select id="getDownShipDynamaics" resultType="java.util.Map">
- --下游港口船舶动态表
- SELECT
- DISTINCT
- OSI.SHIPMENT_INSTRUCTIONS_ID "instructionsId",
- OIC.INSTRUCTIONS_CAPACITY_ID "instructionsCapacityId",
- ADN.PORT_ID "adnPortId",
- WGM.GM_ID "gmId",
- WGM.PORT_ID "portId",
- WGM.BATCH_ID "batchId",
- RP.PORT_NAME "portName",
- RM.MATERIAL_NAME || '(' || DB.RESULT_FOREIGN_SHIP_NAME || ')' || ADN.RESULT_NUMBER_OF_LOANS || '吨,' || TO_CHAR(ADN.NOTICE_DELIVERY_TIME,'YYYY-MM-DD') ||'放货'
- ||
- (case
- when OSI.HANDOVER_MODE IS NULL
- then ''
- else '(二程:' || OSI.HANDOVER_MODE || ')'
- end) "productName",
- WGM.GM_TONNAGE "gmTonnage",
- (case
- when TWQR.IS_NEED_ASSEMBLE = '是'
- then RC.CAPACITY_NUMBER ||'(拼装)'
- else RC.CAPACITY_NUMBER
- end)
- "capacityNumber",
- oic.INSTRUCTION_PLANNED_LOADING "planLoadTon",
- oic.INSTRUCTIONS_SHIP_POSITION "position",
- TLSR.RESULT_ACTUAL_INSTALLATIONS "actualLoadTon",
- oic.SHIP_DYNAMIC "shipDynamic",
- oic.LOAD_DETAILS "loadDetails",
- ADN.NOTICE_DELIVERY_TIME "noticeDeliveryTime"
- from AMSSHIP_DELIVERY_NOTICE ADN
- LEFT JOIN RMS_PORT RP
- ON RP.PORT_ID = ADN.PORT_ID
- LEFT JOIN OMSSHIP_SHIPMENT_INSTRUCTIONS OSI
- ON OSI.BATCH_ID = ADN.BATCH_ID
- LEFT JOIN OMSSHIP_INSTRUCTIONS_CAPACITY OIC
- ON OIC.INSTRUCTIONS_ID = OSI.SHIPMENT_INSTRUCTIONS_ID
- LEFT JOIN RMS_CAPACITY RC
- ON RC.CAPACITY_ID =OIC.CAPACITY_ID
- LEFT JOIN DIL_BATCH_INFACOTRY DBI
- ON DBI.BATCH_INFACOTRY_ID = ADN.BATCH_ID
- LEFT JOIN DIL_BATCH DB
- ON DB.BATCH_ID = DBI.BATCH_ID
- left join RMS_MATERIAL RM
- ON RM.MATERIAL_ID = DB.MATERIAL_ID
- LEFT JOIN WMSH_GRID_MATERIAL WGM
- ON WGM.BATCH_ID = DB.BATCH_ID AND ADN.PORT_ID=WGM.PORT_ID
- LEFT JOIN TMSSHIP_TOTAL_RESULT TTR
- ON OIC.INSTRUCTIONS_CAPACITY_ID=TTR.ORDER_ID
- LEFT JOIN TMSSHIP_WATER_QUALITY_RESULT TWQR
- ON TWQR.TOTAL_RESULT_ID=TTR.RESULT_ID
- LEFT JOIN TMSSHIP_LOAD_SHIP_RESULT TLSR
- ON TLSR.TOTAL_RESULT_ID=TTR.RESULT_ID
- <where>
- ADN.DELETED=0
- <if test="input !=null and input.toString()!=''">
- and RC.CAPACITY_NUMBER || RP.PORT_NAME || DB.RESULT_FOREIGN_SHIP_NAME || rm.MATERIAL_NAME like concat('%',concat(#{input},'%'))
- </if>
- <if test="oneDate != null">
- and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') <= ADN.NOTICE_DELIVERY_TIME
- </if>
- <if test="startDate != null">
- and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') <= ADN.NOTICE_DELIVERY_TIME
- and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= ADN.NOTICE_DELIVERY_TIME
- </if>
- </where>
- ORDER BY RP.PORT_NAME,ADN.NOTICE_DELIVERY_TIME DESC
- </select>
- <select id="getPleaseData" resultType="java.util.Map">
- select sum(RESULT_APPROVE_NUMBER) "approveSum",sum(RESULT_SURPLUS_NUMBER) "surplusSum" from TMSTRAIN_PLEASE_RESULT
- where DELETED=0
- <if test="oneDate != null">
- and to_date(#{oneDate}, 'yyyy-mm-dd hh24:mi:ss') <= RESULT_DATE
- </if>
- <if test="startDate != null">
- and to_date(#{startDate}, 'yyyy-mm-dd hh24:mi:ss') <= RESULT_DATE
- and to_date(#{endDate}, 'yyyy-mm-dd hh24:mi:ss') >= RESULT_DATE
- </if>
- </select>
- <select id="getRealNumberMonth" resultType="java.math.BigDecimal">
- select count(TLT.RESULT_ID) from TMSTRAIN_LOADING_TEMP TLT,WMSH_OUTBOUND_RESULT WOR
- where TLT.OUTBOUNT_ID=WOR.RESULT_ID
- AND #{monthDate} = TO_CHAR(WOR.INSERT_TIME,'YYYY-MM')
- </select>
- <select id="selectAllUnload" resultType="java.util.Map">
- SELECT *
- FROM (
- select DISTINCT
- db.BATCH_ID "batchId",
- DBI2.BATCH_INFACOTRY_ID "batchInfacoryId",
- db.result_foreign_ship_name "shipName",
- rm.material_name "materialName",
- RMT.MATERIAL_TYPE_NAME "materialTypeName",
- adn.NOTICE_DELIVERY_TIME "dateOfLoans",
- adn.RESULT_NUMBER_OF_LOANS "numberOfLoans",
- rp.port_name "portName",
- wgm.gm_tonnage "tonnage"
- from AMSSHIP_DELIVERY_NOTICE adn
- LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
- LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
- JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
- join rms_material rm on db.material_id=rm.material_id
- left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
- left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
- left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
- where adn.DELETED=0 and wgm.DELETED=0 and wgm.gm_tonnage>0
- and DBI2.BATCH_INFACOTRY_ID not in(
- select DISTINCT
- DBI2.BATCH_INFACOTRY_ID "batchInfacoryId"
- from AMSSHIP_DELIVERY_NOTICE adn
- LEFT JOIN DIL_BATCH_INFACOTRY DBI2 on adn.batch_id=DBI2.BATCH_INFACOTRY_ID
- LEFT JOIN AMSSHIP_DELIVERY_ATTORNEY ADA ON ADA.BATCH_ID = adn.batch_id
- JOIN DIL_BATCH DB ON DBI2.BATCH_ID=DB.BATCH_ID
- join rms_material rm on db.material_id=rm.material_id
- left join rms_port rp on rp.port_id=ADA.DOWN_SWIM_PORT_ID
- left join WMSH_GRID_MATERIAL wgm on wgm.batch_id = DB.BATCH_ID AND ADA.DOWN_SWIM_PORT_ID=WGM.PORT_ID
- left join TMSSHIP_LOAD_SHIP_RESULT tlsr on DBI2.BATCH_INFACOTRY_ID=tlsr.batch_id
- left join tmsship_total_result ttr on ttr.result_id=tlsr.TOTAL_RESULT_ID
- left join omsship_instructions_capacity oic on ttr.order_id=oic.instructions_capacity_id
- left join OMSSHIP_SHIPMENT_INSTRUCTIONS OSI ON OSI.SHIPMENT_INSTRUCTIONS_ID=oic.INSTRUCTIONS_ID
- left join rms_capacity rc on oic.capacity_id=rc.capacity_id
- left join RMS_MATERIAL_TYPE RMT on adn.MATERIAL_TYPE_ID = RMT.MATERIAL_TYPE_ID
- left join (select * from tmsship_ship_location t where t.location_id in
- (SELECT
- t.location_id
- FROM
- (
- SELECT
- t.location_id,
- t.total_result_id,
- t.location_route_time,
- ROW_NUMBER () OVER (
- PARTITION BY t.total_result_id
- ORDER BY t.location_route_time DESC
- ) AS rn
- FROM
- tmsship_ship_location t
- ) t
- WHERE
- rn = 1)) tsl on tsl.total_result_id=ttr.result_id
- where ttr.ship_status = 0 and tsl.LOCATION_STATUS is not null and tlsr.DELETED=0
- and adn.DELETED=0 and oic.DELETED=0
- )
- )
- <if test="con!=null and con!=''.toString()">
- WHERE instr( "materialName", #{con} ) > 0 OR instr( "shipName", #{con} ) > 0
- </if>
- Order By "batchInfacoryId" DESC
- </select>
- </mapper>
|