diff --git a/src/main/resources/mybatis/mapper/crdn/crndRegistAndView/main/CrdnRegistAndViewMapper_maria.xml b/src/main/resources/mybatis/mapper/crdn/crndRegistAndView/main/CrdnRegistAndViewMapper_maria.xml index f21d345..29b611b 100644 --- a/src/main/resources/mybatis/mapper/crdn/crndRegistAndView/main/CrdnRegistAndViewMapper_maria.xml +++ b/src/main/resources/mybatis/mapper/crdn/crndRegistAndView/main/CrdnRegistAndViewMapper_maria.xml @@ -507,98 +507,110 @@ /* 중요로직: 기존 selectList와 동일하되, 부과금액(tb_levy_info.IMPLT_CPSR_AMT)과 향후절차(다음 진행코드) 추가 */ SELECT m.* FROM ( - SELECT - c.CRDN_YR, /* 단속 연도 */ - c.CRDN_NO, /* 단속 번호 */ - c.SGG_CD, /* 시군구 코드 */ - sgg.CD_NM AS SGG_CD_NM, - c.RGN_SE_CD, /* 지역 구분 코드 */ - rgn.CD_NM AS RGN_SE_CD_NM, - c.DSCL_MTHD_CD, /* 단속 방법 코드 */ - dscl.CD_NM AS DSCL_MTHD_CD_NM, - c.DSCL_YMD, /* 적발 일자 */ - c.EXMNR, /* 조사원 */ - c.RMRK, /* 비고 (특이사항) */ - c.DSPS_BFHD_BGNG_YMD, /* 사전처분 시작일 */ - c.DSPS_BFHD_END_YMD, /* 사전처분 종료일 */ - c.CRC_CMD_BGNG_YMD, /* 시정명령 시작일 */ - c.CRC_CMD_END_YMD, /* 시정명령 종료일 */ - c.CRC_URG_BGNG_YMD, /* 시정촉구 시작일 */ - c.CRC_URG_END_YMD, /* 시정촉구 종료일 */ - c.LEVY_PRVNTC_BGNG_YMD, /* 부과예고 시작일 */ - c.LEVY_PRVNTC_END_YMD, /* 부과예고 종료일 */ - c.LEVY_BGNG_YMD, /* 부과 시작일 */ - c.LEVY_END_YMD, /* 부과 종료일 */ - c.PAY_URG_BGNG_YMD, /* 납부촉구 시작일 */ - c.PAY_URG_END_YMD, /* 납부촉구 종료일 */ - c.FRST_CRDN_YR, /* 최초 단속 연도 */ - c.FRST_CRDN_NO, /* 최초 단속 번호 */ - c.RELEVY_YN, /* 재과 여부 */ - c.AGRVTN_LEVY_TRGT_YN, /* 가중 부과 대상 여부 */ - c.CRDN_PRCS_STTS_CD, /* 단속 처리 상태 코드 */ - stts.CD_NM AS CRDN_PRCS_STTS_CD_NM, - c.CRDN_PRCS_YMD, /* 단속 처리 일자 */ - c.REG_DT, - c.RGTR, - u.USER_ACNT AS RGTR_ACNT, - u.USER_NM AS RGTR_NM, - p.LOTNO_WHOL_ADDR, /* 지번 전체 주소 */ - p.STDG_EMD_CD, /* 법정동 읍면동 코드 */ - emd.CD_NM AS STDG_EMD_CD_NM, - p.ZIP, - (SELECT GROUP_CONCAT(DISTINCT o2.FLNM SEPARATOR ', ') - FROM tb_ownr_info oi2 - LEFT JOIN tb_ownr o2 ON o2.OWNR_ID = oi2.OWNR_ID AND o2.DEL_YN = 'N' - WHERE oi2.CRDN_YR = c.CRDN_YR - AND oi2.CRDN_NO = c.CRDN_NO - AND oi2.DEL_YN = 'N') AS OWNR_NAMS, - (SELECT GROUP_CONCAT(DISTINCT o2.FLNM SEPARATOR ', ') - FROM tb_actr_info ai - LEFT JOIN tb_ownr o2 ON o2.OWNR_ID = ai.OWNR_ID AND o2.DEL_YN = 'N' - WHERE ai.CRDN_YR = c.CRDN_YR - AND ai.CRDN_NO = c.CRDN_NO - AND ai.DEL_YN = 'N') AS ACTR_NAMS, - a.ACT_TYPE_CD, /* 행위 유형 코드 */ - CASE WHEN IFNULL(act_cnt.ACT_ALL_CNT, 0) > 1 THEN - CONCAT(act.VLTN_BDST, ' 등 ', act_cnt.ACT_ALL_CNT, '건') - ELSE act.VLTN_BDST END ACT_TYPE_CD_NM, - IFNULL(act_cnt.ACT_ALL_CNT, 0) as ACT_ALL_CNT, - IFNULL(act_cnt.ACT_COMPLT_CNT, 0) as ACT_COMPLT_CNT, - /* 중요로직: ACT_CMPLT_CD를 메인 SELECT에서 직접 계산 - 외부 SELECT에서 재계산 불필요 */ - case when IFNULL(act_cnt.ACT_ALL_CNT, 0) = 0 then '0' - when IFNULL(act_cnt.ACT_ALL_CNT, 0) != 0 and IFNULL(act_cnt.ACT_ALL_CNT, 0) != IFNULL(act_cnt.ACT_COMPLT_CNT, 0) then '1' - when IFNULL(act_cnt.ACT_ALL_CNT, 0) != 0 and IFNULL(act_cnt.ACT_ALL_CNT, 0) = IFNULL(act_cnt.ACT_COMPLT_CNT, 0) then '3' - else '-' - end as ACT_CMPLT_CD, /* [행위정보없음 0: , 미조치 : 1, 조치완료 : 3] */ - a.USG_IDX_CD, /* 용도 지수 코드 */ - usg.USG_NM AS USG_IDX_CD_NM, - /* 엑셀 다운로드 전용 컬럼 */ - CONCAT(c.CRDN_YR, '-', c.CRDN_NO) AS MNG_NO, /* 관리번호 (단속연도-단속번호) */ - '' AS SEWMTR_MNG_NO, /* 세움터 관리번호 (공백 처리) */ - '' AS ACT_YMD, /* 행위일자 (현재 DB에 없음) */ - (SELECT li.IMPLT_CPSR_AMT - FROM tb_levy_info li - WHERE li.CRDN_YR = c.CRDN_YR - AND li.CRDN_NO = c.CRDN_NO - AND li.DEL_YN = 'N' - ORDER BY li.LEVY_INFO_ID - LIMIT 1) AS LEVY_AMT, /* 부과금액 (첫번째 값) */ - '' AS PAY_YMD, /* 납부일자 (공백 처리) */ - (SELECT next_cd.CD_NM - FROM tb_cd_detail curr_cd - LEFT JOIN tb_cd_detail next_cd - ON next_cd.CD_GROUP_ID = 'CRDN_PRCS_STTS_CD' - AND next_cd.USE_YN = 'Y' - AND next_cd.SORT_ORDR = ( - SELECT MIN(ncd.SORT_ORDR) - FROM tb_cd_detail ncd - WHERE ncd.CD_GROUP_ID = 'CRDN_PRCS_STTS_CD' - AND ncd.USE_YN = 'Y' - AND ncd.SORT_ORDR > curr_cd.SORT_ORDR - ) - WHERE curr_cd.CD_GROUP_ID = 'CRDN_PRCS_STTS_CD' - AND curr_cd.CD_ID = c.CRDN_PRCS_STTS_CD) AS NEXT_PRCS_NM /* 향후절차 (다음 진행코드명) */ + /* 중요로직: 엑셀 VO(CrdnRegistAndViewExcelVO) 순서에 맞춰 컬럼 정렬, 사용하지 않는 컬럼은 하단으로 이동 */ + SELECT + /* ===================== [VO 표출 컬럼 - 상단 고정] ===================== */ + CONCAT(c.CRDN_YR, '-', c.CRDN_NO) AS MNG_NO, /* 관리번호 (단속연도-단속번호) */ + '' AS SEWMTR_MNG_NO, /* 세움터 관리번호 (공백 처리) */ + DATE_FORMAT(STR_TO_DATE(c.DSCL_YMD, '%Y%m%d'), '%Y-%m-%d') AS DSCL_YMD, /* 적발 일자 */ + DATE_FORMAT(STR_TO_DATE(ai.ACT_BGNG_YMD, '%Y%m%d'), '%Y년') as ACT_YMD, /* 행위일자 (현재 DB에 없음) */ + CASE + WHEN c.FRST_CRDN_YR IS NULL OR c.FRST_CRDN_NO IS NULL + THEN DATE_FORMAT(STR_TO_DATE(c.CRC_CMD_BGNG_YMD, '%Y%m%d'), '%Y-%m-%d') + ELSE ( + SELECT DATE_FORMAT(STR_TO_DATE(fc.CRC_CMD_BGNG_YMD, '%Y%m%d'), '%Y-%m-%d') + FROM tb_crdn fc + WHERE fc.CRDN_YR = c.FRST_CRDN_YR + AND fc.CRDN_NO = c.FRST_CRDN_NO + AND fc.DEL_YN = 'N' + ) + END AS CRC_CMD_BGNG_YMD, /* 최초 시정명령 */ + DATE_FORMAT(STR_TO_DATE(c.LEVY_BGNG_YMD, '%Y%m%d'), '%Y-%m-%d') AS LEVY_BGNG_YMD, /* 최근 부과일 */ + (SELECT li.IMPLT_CPSR_AMT + FROM tb_levy_info li + WHERE li.CRDN_YR = c.CRDN_YR + AND li.CRDN_NO = c.CRDN_NO + AND li.DEL_YN = 'N' + ORDER BY li.LEVY_INFO_ID + LIMIT 1) AS LEVY_AMT, /* 부과금액 (첫번째 값) */ + '' AS PAY_YMD, /* 납부일자 (공백 처리) */ + p.LOTNO_WHOL_ADDR, /* 번지 (지번 전체 주소) */ + p.DTL_ADDR, /* 상세주소 */ + (SELECT GROUP_CONCAT(DISTINCT o2.FLNM SEPARATOR ', ') + FROM tb_ownr_info oi2 + LEFT JOIN tb_ownr o2 ON o2.OWNR_ID = oi2.OWNR_ID AND o2.DEL_YN = 'N' + WHERE oi2.CRDN_YR = c.CRDN_YR + AND oi2.CRDN_NO = c.CRDN_NO + AND oi2.DEL_YN = 'N') AS OWNR_NAMS, /* 소유자(건축주) */ + (SELECT GROUP_CONCAT(DISTINCT o2.FLNM SEPARATOR ', ') + FROM tb_actr_info ari + LEFT JOIN tb_ownr o2 ON o2.OWNR_ID = ari.OWNR_ID AND o2.DEL_YN = 'N' + WHERE ari.CRDN_YR = c.CRDN_YR + AND ari.CRDN_NO = c.CRDN_NO + AND ari.ACT_INFO_ID = ai.ACT_INFO_ID + AND ari.DEL_YN = 'N') AS ACTR_NAMS, /* 행위자(상호) */ + c.AGRVTN_LEVY_TRGT_YN, /* 가중부과 대상 여부 */ + act.VLTN_BDST AS ACT_TYPE_CD_NM, /* 불법행위 */ + '' AS ACT_DTL_CN, /* 세부내용 (현재 DB에 없음) */ + usg.USG_NM AS USG_IDX_CD_NM, /* 용도 */ + '' AS USG_DTL_CN, /* 세부용도 (현재 DB에 없음) */ + ROUND(CAST(ai.AREA AS DECIMAL(10,2)) - CAST(IFNULL(ai.ACTN_WHOL_AREA, 0) AS DECIMAL(10,2)), 2) AS ILLEGAL_AREA, /* 불법면적 */ + strct_ai.STRCT_NM, /* 구조 (구조지수명) */ + '' AS REMAIN_DAYS, /* 남은일 (현재 DB에 없음) */ + stts.CD_NM AS CRDN_PRCS_STTS_CD_NM, /* 처분내용 (진행단계) */ + c.CRDN_PRCS_YMD, /* 처분일 */ + (SELECT next_cd.CD_NM + FROM tb_cd_detail curr_cd + LEFT JOIN tb_cd_detail next_cd + ON next_cd.CD_GROUP_ID = 'CRDN_PRCS_STTS_CD' + AND next_cd.USE_YN = 'Y' + AND next_cd.SORT_ORDR = ( + SELECT MIN(ncd.SORT_ORDR) + FROM tb_cd_detail ncd + WHERE ncd.CD_GROUP_ID = 'CRDN_PRCS_STTS_CD' + AND ncd.USE_YN = 'Y' + AND ncd.SORT_ORDR > curr_cd.SORT_ORDR + ) + WHERE curr_cd.CD_GROUP_ID = 'CRDN_PRCS_STTS_CD' + AND curr_cd.CD_ID = c.CRDN_PRCS_STTS_CD) AS NEXT_PRCS_NM, /* 향후절차 */ + '' AS DEADLINE, /* 기한 (현재 DB에 없음) */ + c.RMRK, /* 특이사항 (비고) */ + '' AS TELNO, /* 연락처 (현재 DB에 없음) */ + /* ===================== [VO 비표출/추가 정보 - 하단] ===================== */ + c.CRDN_YR, /* 단속 연도 */ + c.CRDN_NO, /* 단속 번호 */ + c.SGG_CD, /* 시군구 코드 */ + sgg.CD_NM AS SGG_CD_NM, + c.RGN_SE_CD, /* 지역 구분 코드 */ + rgn.CD_NM AS RGN_SE_CD_NM, + c.DSCL_MTHD_CD, /* 단속 방법 코드 */ + dscl.CD_NM AS DSCL_MTHD_CD_NM, + c.EXMNR, /* 조사원 */ + DATE_FORMAT(STR_TO_DATE(c.DSPS_BFHD_BGNG_YMD, '%Y%m%d'), '%Y-%m-%d') AS DSPS_BFHD_BGNG_YMD, /* 사전처분 시작일 */ + DATE_FORMAT(STR_TO_DATE(c.DSPS_BFHD_END_YMD, '%Y%m%d'), '%Y-%m-%d') AS DSPS_BFHD_END_YMD, /* 사전처분 종료일 */ + DATE_FORMAT(STR_TO_DATE(c.CRC_CMD_END_YMD, '%Y%m%d'), '%Y-%m-%d') AS CRC_CMD_END_YMD, /* 시정명령 종료일 */ + DATE_FORMAT(STR_TO_DATE(c.CRC_URG_BGNG_YMD, '%Y%m%d'), '%Y-%m-%d') AS CRC_URG_BGNG_YMD, /* 시정촉구 시작일 */ + DATE_FORMAT(STR_TO_DATE(c.CRC_URG_END_YMD, '%Y%m%d'), '%Y-%m-%d') AS CRC_URG_END_YMD, /* 시정촉구 종료일 */ + DATE_FORMAT(STR_TO_DATE(c.LEVY_PRVNTC_BGNG_YMD, '%Y%m%d'), '%Y-%m-%d') AS LEVY_PRVNTC_BGNG_YMD, /* 부과예고 시작일 */ + DATE_FORMAT(STR_TO_DATE(c.LEVY_PRVNTC_END_YMD, '%Y%m%d'), '%Y-%m-%d') AS LEVY_PRVNTC_END_YMD, /* 부과예고 종료일 */ + DATE_FORMAT(STR_TO_DATE(c.LEVY_END_YMD, '%Y%m%d'), '%Y-%m-%d') AS LEVY_END_YMD, /* 부과 종료일 */ + DATE_FORMAT(STR_TO_DATE(c.PAY_URG_BGNG_YMD, '%Y%m%d'), '%Y-%m-%d') AS PAY_URG_BGNG_YMD, /* 납부촉구 시작일 */ + DATE_FORMAT(STR_TO_DATE(c.PAY_URG_END_YMD, '%Y%m%d'), '%Y-%m-%d') AS PAY_URG_END_YMD, /* 납부촉구 종료일 */ + c.FRST_CRDN_YR, /* 최초 단속 연도 */ + c.FRST_CRDN_NO, /* 최초 단속 번호 */ + c.RELEVY_YN, /* 재과 여부 */ + c.CRDN_PRCS_STTS_CD, /* 단속 처리 상태 코드 */ + c.REG_DT, + c.RGTR, + u.USER_ACNT AS RGTR_ACNT, + u.USER_NM AS RGTR_NM, + p.STDG_EMD_CD, /* 법정동 읍면동 코드 */ + emd.CD_NM AS STDG_EMD_CD_NM, + p.ZIP, + ai.ACT_TYPE_CD, /* 행위 유형 코드 */ + ai.USG_IDX_CD /* 용도 지수 코드 */ FROM tb_crdn c + inner join tb_act_info ai on ai.CRDN_NO = c.CRDN_NO and ai.CRDN_YR = c.CRDN_YR and ai.DEL_YN = 'N' LEFT JOIN tb_cd_detail sgg ON sgg.CD_GROUP_ID = 'ORG_CD' AND sgg.CD_ID = c.SGG_CD LEFT JOIN tb_cd_detail rgn ON rgn.CD_GROUP_ID = 'RGN_SE_CD' AND rgn.CD_ID = c.RGN_SE_CD LEFT JOIN tb_cd_detail dscl ON dscl.CD_GROUP_ID = 'DSCL_MTHD_CD' AND dscl.CD_ID = c.DSCL_MTHD_CD @@ -606,19 +618,9 @@ LEFT JOIN tb_user u ON u.USER_ID = c.RGTR AND u.USE_YN = 'Y' LEFT JOIN tb_pstn_info p ON p.CRDN_YR = c.CRDN_YR AND p.CRDN_NO = c.CRDN_NO AND p.DEL_YN = 'N' LEFT JOIN tb_cd_detail emd ON emd.CD_GROUP_ID = 'STDG_EMD_CD' AND emd.CD_ID = p.STDG_EMD_CD - LEFT JOIN ( - SELECT - CRDN_YR, - CRDN_NO, - COUNT(1) as ACT_ALL_CNT, - SUM(CASE WHEN ACTN_PRCS_STTS_CD = '3' THEN 1 ELSE 0 END) as ACT_COMPLT_CNT - FROM tb_act_info - WHERE DEL_YN = 'N' - GROUP BY CRDN_YR, CRDN_NO - ) act_cnt ON act_cnt.CRDN_YR = c.CRDN_YR AND act_cnt.CRDN_NO = c.CRDN_NO - LEFT Join tb_act_info a ON a.CRDN_YR = c.CRDN_YR and a.CRDN_NO = c.CRDN_NO AND a.DEL_YN = 'N' AND a.ACT_NO = (SELECT MIN(a1.ACT_NO) FROM tb_act_info a1 WHERE a1.CRDN_YR = a.CRDN_YR AND a1.CRDN_NO = a.CRDN_NO AND a1.DEL_YN='N') - LEFT JOIN tb_act_type act ON act.ACT_TYPE_CD = a.ACT_TYPE_CD - LEFT JOIN tb_usg_idx usg ON usg.USG_IDX_CD = a.USG_IDX_CD AND usg.DEL_YN = 'N' + LEFT JOIN tb_act_type act ON act.ACT_TYPE_CD = ai.ACT_TYPE_CD + LEFT JOIN tb_usg_idx usg ON usg.USG_IDX_CD = ai.USG_IDX_CD + LEFT JOIN tb_strct_idx strct_ai ON strct_ai.STRCT_IDX_CD = ai.STRCT_IDX_CD WHERE c.DEL_YN = 'N' AND c.CRDN_YR = #{schCrdnYr} @@ -661,10 +663,6 @@ ) m WHERE 1=1 - - /* 중요로직: ACT_CMPLT_CD가 메인 SELECT에서 이미 계산되어 단순 비교만 수행 */ - AND m.ACT_CMPLT_CD = #{schActCmpltCd} /* [행위정보없음 0: , 미조치 : 1, 조치완료 : 3] */ - ORDER BY m.CRDN_YR DESC, m.CRDN_NO DESC