Files
wace_plm/src/com/pms/mapper/customerMng.xml
chpark da06c4684c Initial commit: WACE PLM with database initialization features
- Add Docker Compose configurations for dev, prod, and standalone environments
- Add database initialization scripts (init-db.sh, init-db-docker.sh)
- Add enhanced start-docker-linux.sh with DB init support
- Add comprehensive database initialization guide
- Support for automatic dbexport.pgsql import on first run
- Include safety checks for production environment
2025-08-29 15:46:08 +09:00

392 lines
14 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="customerMng">
<sql id="customerMngBase">
(
SELECT
OBJID,
MNG_NUMBER,
MNG_TYPE,
PRODUCT_DIVISION,
PROJECT_OBJID,
(SELECT PROJECT_NO FROM ORDER_MGMT O WHERE O.ORDER_MGMT_OBJID = T.PROJECT_OBJID) AS PROJECT_NO,
RECEPTION_DATE,
TO_CHAR(T.RECEPTION_DATE,'YYYY-MM-DD') AS RECEPTION_DATE_TITLE,
EVENT_LOCATION,
ACTION_DATE,
TO_CHAR(T.ACTION_DATE,'YYYY-MM-DD') AS ACTION_DATE_TITLE,
CUSTOMER_NAME,
TITLE,
PERFORMER,
WRITER,
(SELECT DEPT_NAME||' '||USER_NAME FROM USER_INFO WHERE USER_ID = T.WRITER) AS WRITER_TITLE,
ANALYSIS,
MEASURE,
MEASURE_TYPE,
MEASURE_AMOUNT,
REGDATE,
EDITDATE,
TO_CHAR(T.REGDATE,'YYYY-MM-DD') AS REGDATE_TITLE,
TO_CHAR(T.REGDATE,'YYYY') AS REGDATE_YEAR_TITLE,
TO_CHAR(T.EDITDATE,'YYYY-MM-DD') AS EDITDATE_TITLE,
STATUS,
A.APPR_STATUS,
A.ROUTE_OBJID,
A.APPROVAL_OBJID
FROM
CUSTOMER_MNG T
LEFT OUTER JOIN
(
SELECT
B.OBJID AS ROUTE_OBJID,
CASE B.STATUS
WHEN 'inProcess' THEN '결재중'
WHEN 'complete' THEN '결재완료'
WHEN 'reject' THEN '반려'
ELSE ''
END APPR_STATUS,
A.OBJID AS APPROVAL_OBJID,
A.TARGET_OBJID,
B.ROUTE_SEQ
FROM
APPROVAL A,
(
select
T1.*
from
(
select
TARGET_OBJID,
max(T.ROUTE_SEQ) as ROUTE_SEQ
from
ROUTE T
group by
T.TARGET_OBJID
) T,
ROUTE T1
where
T.TARGET_OBJID = T1.TARGET_OBJID
and T.ROUTE_SEQ = T1.ROUTE_SEQ
) B
WHERE
A.OBJID = B.APPROVAL_OBJID
AND TARGET_TYPE IN ('CUSTOMER_MNG')
) A
ON T.OBJID::numeric = A.TARGET_OBJID
)
</sql>
<!-- 고객관리 목록을 가져온다. -->
<select id="getCustomerMngList" parameterType="map" resultType="map">
SELECT *
FROM(
SELECT T.*, ROW_NUMBER() OVER(ORDER BY REGDATE DESC) RNUM
FROM(
SELECT
T.*
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.MNG_TYPE AND O.PARENT_CODE_ID = #{MNG_TYPE_CD}) AS MNG_TYPE_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.PRODUCT_DIVISION AND O.PARENT_CODE_ID = #{PRODUCT_DIVISION_CD}) AS PRODUCT_DIVISION_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.PERFORMER AND O.PARENT_CODE_ID = #{PERFORMER_CD}) AS PERFORMER_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.MEASURE_TYPE AND O.PARENT_CODE_ID = #{MEASURE_TYPE_CD}) AS MEASURE_TYPE_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.STATUS AND O.PARENT_CODE_ID = #{CUSTOMER_MNG_STATUS_CD}) AS STATUS_TITLE
FROM <include refid="customerMngBase"/> T
WHERE 1=1
<if test="search_year != null and search_year != ''">
AND T.REGDATE_YEAR_TITLE = #{search_year}
</if>
<if test="search_mng_type != null and search_mng_type != ''">
AND T.MNG_TYPE = #{search_mng_type}
</if>
<if test="search_product_division != null and search_product_division != ''">
AND T.PRODUCT_DIVISION = #{search_product_division}
</if>
<if test="search_project_objid != null and search_project_objid != ''">
AND T.PROJECT_OBJID = #{search_project_objid}::numeric
</if>
<if test="search_customer_name != null and search_customer_name != ''">
AND T.CUSTOMER_NAME like '%${search_customer_name}%'
</if>
<if test="search_start_reception_date != null and search_start_reception_date != ''">
<![CDATA[ AND RECEPTION_DATE_TITLE >= #{search_start_reception_date} ]]>
</if>
<if test="search_end_reception_date != null and search_end_reception_date != ''">
<![CDATA[ AND RECEPTION_DATE_TITLE <= #{search_end_reception_date} ]]>
</if>
<if test="search_event_location != null and search_event_location != ''">
AND T.EVENT_LOCATION like '%${search_event_location}%'
</if>
<if test="search_performer != null and search_performer != ''">
AND T.PERFORMER = #{search_performer}
</if>
<if test="search_start_action_date != null and search_start_action_date != ''">
<![CDATA[ AND T.ACTION_DATE_TITLE >= #{search_start_action_date} ]]>
</if>
<if test="search_end_action_date != null and search_end_action_date != ''">
<![CDATA[ AND T.ACTION_DATE_TITLE <= #{search_end_action_date} ]]>
</if>
<if test="search_measure_type != null and search_measure_type != ''">
AND T.MEASURE_TYPE = #{search_measure_type}
</if>
<if test="search_status != null and search_status != ''">
AND T.STATUS = #{search_status}
</if>
) T
) A WHERE 1=1
AND <![CDATA[ RNUM::integer <= #{PAGE_END}::integer ]]>
AND <![CDATA[ RNUM::integer >= #{PAGE_START}::integer]]>
</select>
<select id="getCustomerMngListCnt" parameterType="map" resultType="map">
SELECT
CEIL(TOTAL_CNT/#{COUNT_PER_PAGE})::numeric::integer AS MAX_PAGE_SIZE,
TOTAL_CNT::integer,
SUM_MEASURE_AMOUNT
FROM (
SELECT
COUNT(1)::float TOTAL_CNT,
SUM(CAST_MEASURE_AMOUNT::numeric) SUM_MEASURE_AMOUNT
FROM(
SELECT
T.*
,CASE
WHEN T.MEASURE_AMOUNT != '' AND 0 <![CDATA[ < ]]> CAST (T.MEASURE_AMOUNT AS INTEGER) AND T.MEASURE_AMOUNT IS NOT NULL
THEN T.MEASURE_AMOUNT
ELSE '0'
END CAST_MEASURE_AMOUNT
FROM <include refid="customerMngBase"/> T
WHERE 1=1
<if test="search_year != null and search_year != ''">
AND T.REGDATE_YEAR_TITLE = #{search_year}
</if>
<if test="search_mng_type != null and search_mng_type != ''">
AND T.MNG_TYPE = #{search_mng_type}
</if>
<if test="search_product_division != null and search_product_division != ''">
AND T.PRODUCT_DIVISION = #{search_product_division}
</if>
<if test="search_project_objid != null and search_project_objid != ''">
AND T.PROJECT_OBJID = #{search_project_objid}::numeric
</if>
<if test="search_customer_name != null and search_customer_name != ''">
AND T.CUSTOMER_NAME like '%${search_customer_name}%'
</if>
<if test="search_start_reception_date != null and search_start_reception_date != ''">
<![CDATA[ AND RECEPTION_DATE_TITLE >= #{search_start_reception_date} ]]>
</if>
<if test="search_end_reception_date != null and search_end_reception_date != ''">
<![CDATA[ AND RECEPTION_DATE_TITLE <= #{search_end_reception_date} ]]>
</if>
<if test="search_event_location != null and search_event_location != ''">
AND T.EVENT_LOCATION like '%${search_event_location}%'
</if>
<if test="search_performer != null and search_performer != ''">
AND T.PERFORMER = #{search_performer}
</if>
<if test="search_start_action_date != null and search_start_action_date != ''">
<![CDATA[ AND T.ACTION_DATE_TITLE >= #{search_start_action_date} ]]>
</if>
<if test="search_end_action_date != null and search_end_action_date != ''">
<![CDATA[ AND T.ACTION_DATE_TITLE <= #{search_end_action_date} ]]>
</if>
<if test="search_measure_type != null and search_measure_type != ''">
AND T.MEASURE_TYPE = #{search_measure_type}
</if>
<if test="search_status != null and search_status != ''">
AND T.STATUS = #{search_status}
</if>
) T
)A WHERE 1=1
</select>
<select id="getCustomerMngInfo" parameterType="map" resultType="map">
SELECT
T.*
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.MNG_TYPE AND O.PARENT_CODE_ID = #{MNG_TYPE_CD}) AS MNG_TYPE_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.PRODUCT_DIVISION AND O.PARENT_CODE_ID = #{PRODUCT_DIVISION_CD}) AS PRODUCT_DIVISION_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.PERFORMER AND O.PARENT_CODE_ID = #{PERFORMER_CD}) AS PERFORMER_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.MEASURE_TYPE AND O.PARENT_CODE_ID = #{MEASURE_TYPE_CD}) AS MEASURE_TYPE_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.STATUS AND O.PARENT_CODE_ID = #{CUSTOMER_MNG_STATUS_CD}) AS STATUS_TITLE
FROM <include refid="customerMngBase"/> T
WHERE 1=1
AND T.OBJID = #{OBJID}::numeric
</select>
<!-- 중고관리 merge -->
<update id="mergeCustomerMng" parameterType="map">
INSERT INTO CUSTOMER_MNG
(
OBJID,
MNG_NUMBER,
MNG_TYPE,
PRODUCT_DIVISION,
<if test="PROJECT_OBJID != null and PROJECT_OBJID != ''">
PROJECT_OBJID,
</if>
<if test="RECEPTION_DATE != null and RECEPTION_DATE != ''">
RECEPTION_DATE,
</if>
EVENT_LOCATION,
<if test="ACTION_DATE != null and ACTION_DATE != ''">
ACTION_DATE,
</if>
CUSTOMER_NAME,
TITLE,
PERFORMER,
WRITER,
ANALYSIS,
MEASURE,
MEASURE_TYPE,
MEASURE_AMOUNT,
REGDATE,
STATUS
)
VALUES
(
#{OBJID}::numeric,
to_char(now(),'YYYY')||'-'||LPAD((select coalesce(substring(max(MNG_NUMBER),6,3),'0')::numeric+1 from CUSTOMER_MNG)::text, 3, '0'),
#{MNG_TYPE},
#{PRODUCT_DIVISION},
<if test="PROJECT_OBJID != null and PROJECT_OBJID != ''">
#{PROJECT_OBJID}::numeric,
</if>
<if test="RECEPTION_DATE != null and RECEPTION_DATE != ''">
#{RECEPTION_DATE}::TIMESTAMP,
</if>
#{EVENT_LOCATION},
<if test="ACTION_DATE != null and ACTION_DATE != ''">
#{ACTION_DATE}::TIMESTAMP,
</if>
#{CUSTOMER_NAME},
#{TITLE},
#{PERFORMER},
#{WRITER},
#{ANALYSIS},
#{MEASURE},
#{MEASURE_TYPE},
#{MEASURE_AMOUNT},
now(),
#{STATUS}
) ON CONFLICT (OBJID) DO
UPDATE
SET
MNG_NUMBER =#{MNG_NUMBER},
MNG_TYPE =#{MNG_TYPE},
PRODUCT_DIVISION =#{PRODUCT_DIVISION},
<if test="PROJECT_OBJID != null and PROJECT_OBJID != ''">
PROJECT_OBJID =#{PROJECT_OBJID}::numeric,
</if>
<if test="RECEPTION_DATE != null and RECEPTION_DATE != ''">
RECEPTION_DATE =#{RECEPTION_DATE}::TIMESTAMP,
</if>
EVENT_LOCATION =#{EVENT_LOCATION},
<if test="ACTION_DATE != null and ACTION_DATE != ''">
ACTION_DATE =#{ACTION_DATE}::TIMESTAMP,
</if>
CUSTOMER_NAME =#{CUSTOMER_NAME},
TITLE =#{TITLE},
PERFORMER =#{PERFORMER},
WRITER =#{WRITER},
ANALYSIS =#{ANALYSIS},
MEASURE =#{MEASURE},
MEASURE_TYPE =#{MEASURE_TYPE},
MEASURE_AMOUNT =#{MEASURE_AMOUNT},
EDITDATE =now(),
STATUS =#{STATUS}
</update>
<delete id="deleteCustomerMng" parameterType="map">
DELETE FROM CUSTOMER_MNG WHERE OBJID = #{OBJID}::numeric
</delete>
<select id="getCustomerMngDashBoard" parameterType="map" resultType="map">
SELECT
COUNT(1) AS TOTAL_ISSUE_COUNT,
SUM(T.MEASURE_AMOUNT) AS SUM_MOUNT,
SUM(PAID_MEASURE_AMOUNT) AS SUM_PAID_MEASURE_AMOUNT,
SUM(FREE_MEASURE_AMOUNT) AS SUM_FREE_MEASURE_AMOUNT
<foreach collection="productDivisionList" item="obj">
,SUM(T.${obj.CODE_NAME}${obj.CODE_ID}) as ${obj.CODE_NAME}${obj.CODE_ID}
</foreach>
<foreach collection="performerList" item="obj">
,SUM(T.${obj.CODE_NAME}${obj.CODE_ID}) as ${obj.CODE_NAME}${obj.CODE_ID}
</foreach>
<foreach collection="mngTypeList" item="obj">
,SUM(T.${obj.CODE_NAME}${obj.CODE_ID}) as ${obj.CODE_NAME}${obj.CODE_ID}
</foreach>
FROM(
SELECT
T.MEASURE_TYPE
,T.MEASURE_TYPE_TITLE
,T.PRODUCT_DIVISION
,T.PRODUCT_DIVISION_TITLE
,T.PERFORMER
,T.PERFORMER_TITLE
,T.MNG_TYPE
,T.MNG_TYPE_TITLE
,CASE
WHEN T.MEASURE_TYPE_TITLE = '유상' THEN T.MEASURE_AMOUNT
ELSE 0
END PAID_MEASURE_AMOUNT
,CASE
WHEN T.MEASURE_TYPE_TITLE = '무상' THEN T.MEASURE_AMOUNT
ELSE 0
END FREE_MEASURE_AMOUNT
,T.MEASURE_AMOUNT
<foreach collection="measureTypeList" item="obj">
,CASE
WHEN T.MEASURE_TYPE = #{obj.CODE_ID}
THEN 1
ELSE 0
END ${obj.CODE_NAME}${obj.CODE_ID}
</foreach>
<foreach collection="productDivisionList" item="obj">
,CASE
WHEN T.PRODUCT_DIVISION = #{obj.CODE_ID}
THEN 1
ELSE 0
END ${obj.CODE_NAME}${obj.CODE_ID}
</foreach>
<foreach collection="performerList" item="obj">
,CASE
WHEN T.PERFORMER = #{obj.CODE_ID}
THEN 1
ELSE 0
END ${obj.CODE_NAME}${obj.CODE_ID}
</foreach>
<foreach collection="mngTypeList" item="obj">
,CASE
WHEN T.MNG_TYPE = #{obj.CODE_ID}
THEN 1
ELSE 0
END ${obj.CODE_NAME}${obj.CODE_ID}
</foreach>
from(
SELECT
T.MEASURE_TYPE
,T.PRODUCT_DIVISION
,T.PERFORMER
,T.MNG_TYPE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.MNG_TYPE AND O.PARENT_CODE_ID = #{MNG_TYPE_CD}) AS MNG_TYPE_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.PRODUCT_DIVISION AND O.PARENT_CODE_ID = #{PRODUCT_DIVISION_CD}) AS PRODUCT_DIVISION_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.PERFORMER AND O.PARENT_CODE_ID = #{PERFORMER_CD}) AS PERFORMER_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.MEASURE_TYPE AND O.PARENT_CODE_ID = #{MEASURE_TYPE_CD}) AS MEASURE_TYPE_TITLE
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = T.STATUS AND O.PARENT_CODE_ID = #{CUSTOMER_MNG_STATUS_CD}) AS STATUS_TITLE
,CASE
WHEN T.MEASURE_AMOUNT != '' AND T.MEASURE_AMOUNT IS NOT NULL
THEN T.MEASURE_AMOUNT::numeric
ELSE 0
END MEASURE_AMOUNT
FROM <include refid="customerMngBase"/> T
WHERE 1=1
<if test="search_year != null and search_year != ''">
AND T.REGDATE_YEAR_TITLE = #{search_year}
</if>
) T
) T
</select>
</mapper>