ys_sms_sending_system/bonus-business/src/main/resources/mapper/MonthPlanMapper.xml

558 lines
27 KiB
XML
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

<?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.bonus.digital.mapper.MonthlyPlanMapper">
<insert id="addMonthlyPlanList" useGeneratedKeys="true" keyProperty="monthlyPlanId">
insert into tb_monthly_plan (monthly_plan,inspection_station_id,inspection_station_name,plan_major_id,business_type_id,
project_name,work_content,plan_category_id,tower_base_number,planned_start_time,
planned_end_time,plan_personnel,plan_car_num,plan_skilled_worker_num,plan_auxiliary_worker_num,
plan_sub_car_num,create_user,create_time,actual_working_day)
values (#{monthlyPlan},#{inspectionStationId},#{inspectionStationName},#{planMajorId},#{businessTypeId},
#{projectName},#{workContent},#{planCategoryId},#{towerBaseNumber},#{plannedStartTime},#{plannedEndTime},
#{planPersonnel},#{planCarNum},#{planSkilledWorkerNum},#{planAuxiliaryWorkerNum},#{planSubCarNum},
#{createUser},#{createTime},#{actualWorkingDay})
</insert>
<insert id="addPersonnelArrangement">
insert into tb_personnel_arrangement (monthly_plan_id,day,personnel_names)
values (#{monthlyPlanId},#{day},#{personnelNames})
</insert>
<insert id="addWorkload">
insert into tb_workload (plan_id,workload_category_id,workload_category_name,unit_price,workload_num,data_source)
values (#{planId},#{workloadCategoryId},#{workloadCategoryName},#{unitPrice},#{workloadNum},#{dataSource})
</insert>
<update id="updateMonthlyPlan">
update tb_monthly_plan
<trim prefix="set" suffixOverrides=",">
<if test="monthlyPlan!= null " >
monthly_plan=#{monthlyPlan},
</if>
<if test="inspectionStationId!= null " >
inspection_station_id=#{inspectionStationId},
</if>
<if test="inspectionStationName!= null " >
inspection_station_name=#{inspectionStationName},
</if>
<if test="planMajorId!= null " >
plan_major_id=#{planMajorId},
</if>
<if test="businessTypeId!= null " >
business_type_id=#{businessTypeId},
</if>
<if test="projectName!= null " >
project_name=#{projectName},
</if>
<if test="workContent!= null " >
work_content=#{workContent},
</if>
<if test="planCategoryId!= null " >
plan_category_id=#{planCategoryId},
</if>
<if test="towerBaseNumber!= null " >
tower_base_number=#{towerBaseNumber},
</if>
<if test="plannedStartTime!= null " >
planned_start_time=#{plannedStartTime},
</if>
<if test="plannedEndTime!= null " >
planned_end_time=#{plannedEndTime},
</if>
<if test="planPersonnel!= null " >
plan_personnel=#{planPersonnel},
</if>
<if test="planCarNum!= null " >
plan_car_num=#{planCarNum},
</if>
<if test="planSkilledWorkerNum!= null " >
plan_skilled_worker_num=#{planSkilledWorkerNum},
</if>
<if test="planAuxiliaryWorkerNum!= null " >
plan_auxiliary_worker_num=#{planAuxiliaryWorkerNum},
</if>
<if test="planSubCarNum!= null " >
plan_sub_car_num=#{planSubCarNum},
</if>
<if test="updateTime!= null " >
update_time=#{updateTime},
</if>
<if test="updateUser!= null " >
update_user=#{updateUser},
</if>
<if test="actualWorkingDay!= null " >
actual_working_day=#{actualWorkingDay},
</if>
</trim>
where monthly_plan_id = #{monthlyPlanId}
</update>
<delete id="delMonthlyPlanList">
update tb_monthly_plan set is_active ='0' where monthly_plan_id = #{monthlyPlanId}
</delete>
<delete id="delPersonnelArrangement">
delete from tb_personnel_arrangement where monthly_plan_id = #{monthlyPlanId}
</delete>
<delete id="delWorkload">
delete from tb_workload where plan_id= #{monthlyPlanId}
</delete>
<select id="getPlanMajorList" resultType="com.bonus.digital.dao.MonthlyPlanVo">
select tmp.monthly_plan_id,
tmp.monthly_plan,
tmp.inspection_station_id,
tmp.inspection_station_name,
tmp.plan_major_id,
tmp.business_type_id,
tmp.project_name,
tmp.work_content,
tmp.plan_category_id,
tmp.tower_base_number,
tmp.planned_start_time,
tmp.planned_end_time,
tmp.plan_personnel,
tmp.plan_car_num,
tmp.plan_skilled_worker_num,
tmp.plan_auxiliary_worker_num,
tmp.plan_sub_car_num,
tmp.create_user,
tmp.create_time,
tmp.actual_working_day
from tb_monthly_plan tmp
left join tb_plan_major tpm on tmp.plan_major_id = tpm.plan_major_id
where tmp.is_active = '1'
</select>
<select id="getPersonnelArrangementList" resultType="com.bonus.digital.dao.PersonnelArrangementVo">
select personnel_arrangement_id,monthly_plan_id,"day",personnel_names
from tb_personnel_arrangement where monthly_plan_id = #{monthlyPlanId}
</select>
<select id="getPlanMajorListByMonth" resultType="com.bonus.digital.dao.MonthlyPlanVo">
select tmp.inspection_station_name,
tmp.work_content,
tmp.planned_start_time,
tmp.planned_end_time,
tmp.plan_personnel
from tb_monthly_plan tmp
where tmp.is_active = '1' and tmp.monthly_plan = #{monthlyPlan}
</select>
<select id="getWorkloadSummary" resultType="com.bonus.digital.dao.MonthlyPlanVo">
select
tmp.inspection_station_id,
tmp.inspection_station_name,
tw.workload_category_name,
IFNULL(tw.unit_price, 0) as unit_price,
IFNULL(SUM(tw.workload_num), 0) as total_workload,
IFNULL(SUM(tw.workload_num), 0) * IFNULL(tw.unit_price, 0) as total_amount
from tb_monthly_plan tmp
left join tb_workload tw
on tw.plan_id = tmp.monthly_plan_id
and tw.data_source = '0'
left join tb_plan_management pm
on pm.plan_management_id = tmp.plan_management_id
where tmp.is_active = '1'
<!-- 计划月份筛选 -->
<if test="monthlyPlan != null and monthlyPlan != ''">
AND tmp.monthly_plan = #{monthlyPlan}
</if>
<!-- 运检站筛选 -->
<if test="inspectionStationId != null and inspectionStationId != ''">
AND tmp.inspection_station_id = #{inspectionStationId}
</if>
<!-- 计划专业筛选 -->
<if test="planMajorId != null and planMajorId != ''">
AND tmp.plan_major_id = #{planMajorId}
</if>
<!-- 业务类型筛选 -->
<if test="businessTypeId != null and businessTypeId != ''">
AND tmp.business_type_id = #{businessTypeId}
</if>
<!-- 风险等级筛选 -->
<if test="riskLevel != null and riskLevel != ''">
AND pm.risk_level = #{riskLevel}
</if>
GROUP BY
tmp.inspection_station_id,
tmp.inspection_station_name,
tw.workload_category_name,
tw.unit_price
ORDER BY tmp.inspection_station_name ASC;
</select>
<select id="getCarUseSummary" resultType="com.bonus.digital.dao.MonthlyPlanVo">
select
tmp.inspection_station_id,
tmp.inspection_station_name,
-- 汇总管理用车天数空则补0
IFNULL(SUM(tmp.plan_car_num), 0) as total_manage_car_days,
-- 汇总分包用车天数空则补0
IFNULL(SUM(tmp.plan_sub_car_num), 0) as total_sub_car_days
from tb_monthly_plan tmp
-- 关联计划管理表
left join tb_plan_management pm
on pm.plan_management_id = tmp.plan_management_id
where tmp.is_active = '1'
<!-- 计划月份筛选 -->
<if test="monthlyPlan != null and monthlyPlan != ''">
AND tmp.monthly_plan = #{monthlyPlan}
</if>
<!-- 运检站筛选 -->
<if test="inspectionStationId != null and inspectionStationId != ''">
AND tmp.inspection_station_id = #{inspectionStationId}
</if>
<!-- 计划专业筛选 -->
<if test="planMajorId != null and planMajorId != ''">
AND tmp.plan_major_id = #{planMajorId}
</if>
<!-- 业务类型筛选 -->
<if test="businessTypeId != null and businessTypeId != ''">
AND tmp.business_type_id = #{businessTypeId}
</if>
<!-- 风险等级筛选 -->
<if test="riskLevel != null and riskLevel != ''">
AND pm.risk_level = #{riskLevel}
</if>
GROUP BY
tmp.inspection_station_id,
tmp.inspection_station_name
ORDER BY tmp.inspection_station_name ASC;
</select>
<select id="getOverallSummary" resultType="com.bonus.digital.dao.MonthlyPlanVo">
select
tis.inspection_station_id,
tis.inspection_station_name,
from tb_inspection_station tis
left join tb_monthly_plan tmp
on tis.inspection_station_id = tmp.inspection_station_id
where tis.category = '0'
-- 关联计划管理表
left join tb_plan_management pm
on pm.plan_management_id = tmp.plan_management_id
where tmp.is_active = '1'
<!-- 计划月份筛选 -->
<if test="monthlyPlan != null and monthlyPlan != ''">
AND tmp.monthly_plan = #{monthlyPlan}
</if>
<!-- 运检站筛选 -->
<if test="inspectionStationId != null and inspectionStationId != ''">
AND tmp.inspection_station_id = #{inspectionStationId}
</if>
<!-- 计划专业筛选 -->
<if test="planMajorId != null and planMajorId != ''">
AND tmp.plan_major_id = #{planMajorId}
</if>
<!-- 业务类型筛选 -->
<if test="businessTypeId != null and businessTypeId != ''">
AND tmp.business_type_id = #{businessTypeId}
</if>
<!-- 风险等级筛选 -->
<if test="riskLevel != null and riskLevel != ''">
AND pm.risk_level = #{riskLevel}
</if>
GROUP BY
tis.inspection_station_id,
tis.inspection_station_name
ORDER BY tmp.inspection_station_name ASC;
</select>
<select id="getResourceSummary" resultType="com.bonus.digital.dao.ResourceSummaryVo">
<![CDATA[
SELECT
-- 运检站基础信息
ista.inspection_station_id,
ista.inspection_station_name,
-- 1. 人员基础数据(编制/借调/实际在站)
(SELECT COUNT(p.id)
FROM tb_personnel p
WHERE p.inspection_station_id = ista.inspection_station_id
AND p.is_active = '1') AS compile_num, -- 编制人数
(SELECT COUNT(p.id)
FROM tb_personnel p
WHERE p.inspection_station_id = ista.inspection_station_id
AND p.long_term_secondment = '1'
AND p.is_active = '1') AS secondment_num, -- 长期借调人数
-- 实际在站人数 = 编制 - 借调
compile_num - secondment_num AS actual_station_num,
-- 2. 总工日 = 月份天数 × 实际在站人数
(SELECT DATEDIFF(LAST_DAY(STR_TO_DATE(#{monthlyPlan}, '%Y-%m')),
DATE_FORMAT(STR_TO_DATE(#{monthlyPlan}, '%Y-%m'), '%Y-%m-01')) + 1)
* actual_station_num AS total_workday,
-- ======================================
-- 类型1休假
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '休假'
AND pm.category = '0') AS rest_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '休假'
AND pm.category = '0') AS rest_person_count,
rest_total_days * rest_person_count AS rest_workday,
ROUND(rest_workday / total_workday, 2) AS rest_ratio,
ROUND(rest_workday / actual_station_num, 1) AS rest_avg,
-- ======================================
-- 类型2培训
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '培训'
AND pm.category = '0') AS train_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '培训'
AND pm.category = '0') AS train_person_count,
train_total_days * train_person_count AS train_workday,
ROUND(train_workday / total_workday, 2) AS train_ratio,
ROUND(train_workday / actual_station_num, 1) AS train_avg,
-- ======================================
-- 类型3运行
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '运行'
AND pm.category = '0') AS run_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '运行'
AND pm.category = '0') AS run_person_count,
run_total_days * run_person_count AS run_workday,
ROUND(run_workday / total_workday, 2) AS run_ratio,
ROUND(run_workday / actual_station_num, 1) AS run_avg,
-- ======================================
-- 新增类型4运行视频
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '运行(视频)'
AND pm.category = '0') AS run_video_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '运行(视频)'
AND pm.category = '0') AS run_video_person_count,
run_video_total_days * run_video_person_count AS run_video_workday,
ROUND(run_video_workday / total_workday, 2) AS run_video_ratio,
ROUND(run_video_workday / actual_station_num, 1) AS run_video_avg,
-- ======================================
-- 类型5检修原维护补全TotalDays/PersonCount
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '检修'
AND pm.category = '0') AS maintain_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '检修'
AND pm.category = '0') AS maintain_person_count,
maintain_total_days * maintain_person_count AS maintain_workday,
ROUND(maintain_workday / total_workday, 2) AS maintain_ratio,
ROUND(maintain_workday / actual_station_num, 1) AS maintain_avg,
-- ======================================
-- 新增类型6值班
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '值班'
AND pm.category = '0') AS duty_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '值班'
AND pm.category = '0') AS duty_person_count,
duty_total_days * duty_person_count AS duty_workday,
ROUND(duty_workday / total_workday, 2) AS duty_ratio,
ROUND(duty_workday / actual_station_num, 1) AS duty_avg,
-- ======================================
-- 类型7抢修
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '抢修'
AND pm.category = '0') AS repair_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '抢修'
AND pm.category = '0') AS repair_person_count,
repair_total_days * repair_person_count AS repair_workday,
ROUND(repair_workday / total_workday, 2) AS repair_ratio,
ROUND(repair_workday / actual_station_num, 1) AS repair_avg,
-- ======================================
-- 类型8学习
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '学习'
AND pm.category = '0') AS study_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '学习'
AND pm.category = '0') AS study_person_count,
study_total_days * study_person_count AS study_workday,
ROUND(study_workday / total_workday, 2) AS study_ratio,
ROUND(study_workday / actual_station_num, 1) AS study_avg,
-- ======================================
-- 类型9其他
-- ======================================
(SELECT IFNULL(SUM(DATEDIFF(tmp.planned_end_time, tmp.planned_start_time) + 1), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '其他'
AND pm.category = '0') AS other_total_days,
(SELECT IFNULL(COUNT(DISTINCT t.person_id), 0)
FROM tb_monthly_plan tmp
LEFT JOIN tb_plan_major pm ON tmp.plan_major_id = pm.plan_major_id
LEFT JOIN JSON_TABLE(
IF(tmp.plan_personnel IS NULL OR tmp.plan_personnel = '', '[]',
CONCAT('["', REPLACE(tmp.plan_personnel, ',', '","'), '"]')),
'$[*]' COLUMNS (person_id VARCHAR(50) PATH '$')
) t
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}
AND pm.plan_major_name = '其他'
AND pm.category = '0') AS other_person_count,
other_total_days * other_person_count AS other_workday,
ROUND(other_workday / total_workday, 2) AS other_ratio,
ROUND(other_workday / actual_station_num, 1) AS other_avg,
-- ======================================
-- 类型10未安排修正计算逻辑包含新增类型
-- ======================================
total_workday - (rest_workday + train_workday + run_workday + run_video_workday + maintain_workday + duty_workday + repair_workday + study_workday) AS unarrange_workday,
ROUND(unarrange_workday / total_workday, 2) AS unarrange_ratio,
ROUND(unarrange_workday / actual_station_num, 1) AS unarrange_avg,
-- ======================================
-- 类型11分包用工
-- ======================================
(SELECT IFNULL(SUM(tmp.plan_skilled_worker_num + tmp.plan_auxiliary_worker_num), 0)
FROM tb_monthly_plan tmp
WHERE tmp.inspection_station_id = ista.inspection_station_id
AND tmp.monthly_plan = #{monthlyPlan}) AS subcontract_workday
FROM tb_inspection_station ista
WHERE ista.category = '0' -- 只统计category为0的运检站
AND ista.is_active = '1'
ORDER BY ista.inspection_station_name ASC;
]]>
</select>
</mapper>