localhost-back/src/main/resources/mapper/localvacaMapper.xml
dyhj625 ada6654edd
All checks were successful
LOCALNET-DEV/pipeline/head This commit looks good
휴가쿼리문 수정
2025-03-17 12:32:16 +09:00

129 lines
5.0 KiB
XML

<?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="io.company.localhost.mapper.localvacaMapper">
<!-- 휴가 저장 -->
<insert id="insertVacation" parameterType="io.company.localhost.common.dto.MapDto">
INSERT INTO localvaca (MEMBERSEQ, LOCVACUDT, LOCVACTYP, LOCVACRDT, LOCVACRMM)
VALUES (#{employeeId}, #{date}, #{type}, NOW(), #{receiverId})
</insert>
<!-- 휴가 데이터 삭제 -->
<delete id="deleteVacation" parameterType="long">
DELETE FROM localvaca
WHERE LOCVACSEQ = #{vacationId}
</delete>
<!-- 휴가 정보 조회 -->
<select id="selectVacations" parameterType="map" resultType="io.company.localhost.common.dto.MapDto">
SELECT LOCVACSEQ, MEMBERSEQ, LOCVACUDT, LOCVACTYP, LOCVACRMM
FROM localvaca
WHERE DATE_FORMAT(LOCVACUDT, '%Y-%m') = CONCAT(#{year}, '-', LPAD(#{month}, 2, '0'))
</select>
<!-- 사용자가 사용한 연차 목록 조회 -->
<select id="selectUsedVacations" resultType="io.company.localhost.common.dto.MapDto">
SELECT LOCVACSEQ AS id, LOCVACUDT AS date, LOCVACTYP AS type, LOCVACRMM AS receiverId,
-- 반차(700101, 700102)는 0.5, 연차(700103)는 1로 계산
SUM(CASE
WHEN LOCVACTYP IN ('700101', '700102') THEN 0.5
WHEN LOCVACTYP = '700103' THEN 1
ELSE 0
END) AS used_quota
FROM localvaca
WHERE MEMBERSEQ = #{userId}
AND YEAR(LOCVACUDT) = #{year}
GROUP BY LOCVACUDT, LOCVACTYP, LOCVACRMM
ORDER BY LOCVACUDT DESC
</select>
<!-- 사용자가 받은 연차 목록 조회 -->
<select id="selectReceivedVacations" resultType="io.company.localhost.common.dto.MapDto">
SELECT
LOCVACUDT AS date,
LOCVACTYP AS type,
MEMBERSEQ AS senderId,
-- 반차(700101, 700102)는 0.5, 연차(700103)는 1로 계산하여 받은 연차 수량 저장
SUM(
CASE
WHEN LOCVACTYP IN ('700101', '700102') THEN 0.5
WHEN LOCVACTYP = '700103' THEN 1
ELSE 0
END
) AS received_quota
FROM localvaca
WHERE LOCVACRMM = #{userId} -- 현재 로그인한 사용자가 받은 연차
AND YEAR(LOCVACUDT) = #{year} -- 해당 연도의 데이터만 가져옴
GROUP BY LOCVACUDT, LOCVACTYP, MEMBERSEQ -- 연차를 보낸 사람별로 그룹화
ORDER BY LOCVACUDT DESC;
</select>
<!-- 전체 직원 남은 연차 조회 -->
<select id="selectEmployeeRemainingVacation" resultType="io.company.localhost.common.dto.MapDto">
<![CDATA[
SELECT
nm.MEMBERSEQ AS employeeId,
nm.MEMBERNAM AS employeeName,
nm.MEMBERCDT AS hireDate,
-- 📌 총 연차 계산 (1년 미만: 12개, 이후 기본 15개 + 2년마다 1개 추가)
CASE
WHEN TIMESTAMPDIFF(MONTH, nm.MEMBERCDT, CURDATE()) < 12
THEN 12
ELSE
15 + FLOOR(TIMESTAMPDIFF(YEAR, nm.MEMBERCDT, CURDATE()) / 2)
END AS total_quota,
-- 📌 사용한 연차 개수 (반차 0.5, 연차 1)
COALESCE(lv.used_quota, 0) AS used_quota,
-- 📌 받은 연차 개수 (반차 0.5, 연차 1)
COALESCE(rv.received_quota, 0) AS received_quota,
-- 📌 남은 연차 계산 (총 연차 - 사용 연차 + 받은 연차)
(
CASE
WHEN TIMESTAMPDIFF(MONTH, nm.MEMBERCDT, CURDATE()) < 12
THEN 12
ELSE
15 + FLOOR(TIMESTAMPDIFF(YEAR, nm.MEMBERCDT, CURDATE()) / 2)
END
) - COALESCE(lv.used_quota, 0) + COALESCE(rv.received_quota, 0) AS remaining_quota
FROM netmember nm
-- 📌 사용한 연차 개수 가져오기 (반차는 0.5, 연차는 1로 변환)
LEFT JOIN (
SELECT MEMBERSEQ,
SUM(CASE
WHEN LOCVACTYP IN ('700101', '700102') THEN 0.5
WHEN LOCVACTYP = '700103' THEN 1
ELSE 0
END) AS used_quota
FROM localvaca
GROUP BY MEMBERSEQ
) lv ON nm.MEMBERSEQ = lv.MEMBERSEQ
-- 📌 받은 연차 개수 가져오기 (반차는 0.5, 연차는 1로 변환)
LEFT JOIN (
SELECT LOCVACRMM AS MEMBERSEQ,
SUM(CASE
WHEN LOCVACTYP IN ('700101', '700102') THEN 0.5
WHEN LOCVACTYP = '700103' THEN 1
ELSE 0
END) AS received_quota
FROM localvaca
WHERE LOCVACRMM IS NOT NULL
GROUP BY LOCVACRMM
) rv ON nm.MEMBERSEQ = rv.MEMBERSEQ
WHERE nm.MEMBERDEL = 'N' -- 퇴사자 제외
]]>
</select>
<select id="selectSentVacationCount" resultType="io.company.localhost.common.dto.MapDto">
SELECT COUNT(*) as count FROM localvaca WHERE MEMBERSEQ = #{userId} AND LOCVACRMM = #{receiverId} AND YEAR(LOCVACUDT) = YEAR(NOW())
</select>
</mapper>