- 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
935 lines
28 KiB
XML
935 lines
28 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="devMng">
|
|
<!-- hwangeuidon start********************************************************************************************************** -->
|
|
<!-- 수준에 해당하는 제품과 프로젝트 정보를 가져온다. -->
|
|
<sql id="projectProductBase">
|
|
(
|
|
SELECT
|
|
PPCI.OBJID
|
|
, PPCI.FOREIGN_TYPE AS FOREIGN_TYPE_ORG
|
|
, CASE PPCI.FOREIGN_TYPE
|
|
WHEN 'D' THEN '국내'
|
|
WHEN 'F' THEN '해외'
|
|
ELSE PPCI.FOREIGN_TYPE
|
|
END FOREIGN_TYPE
|
|
, PPCI.OEM_OBJID
|
|
, (SELECT OEM_CODE FROM OEM_MNG WHERE OBJID = PPCI.OEM_OBJID) AS OEM_CODE
|
|
, (SELECT OEM_NAME FROM OEM_MNG WHERE OBJID = PPCI.OEM_OBJID) AS OEM_NAME
|
|
, PPCI.CAR_OBJID
|
|
, (SELECT CAR_CODE FROM CAR_MNG WHERE OBJID = PPCI.CAR_OBJID) AS CAR_CODE
|
|
, (SELECT CAR_NAME FROM CAR_MNG WHERE OBJID = PPCI.CAR_OBJID) AS CAR_NAME
|
|
, (SELECT MODEL_CODE FROM CAR_MNG WHERE OBJID = PPCI.CAR_OBJID) AS CAR_MODEL_CODE
|
|
, (SELECT MILESTONE_DATE FROM PMS_REL_PJT_CONCEPT_MILESTONE WHERE TARGET_OBJID = PPCI.OBJID AND MILESTONE_OBJID IN (SELECT OBJID FROM OEM_MILESTONE_MNG WHERE MILESTONE_NAME = '양산')) AS MILESTONE_DATE
|
|
, PPCI.PJT_TYPE AS PJT_TYPE_ORG
|
|
, CASE UPPER(PPCI.PJT_TYPE) WHEN 'NEW' THEN '신차'
|
|
WHEN 'DERIVATIVE' THEN '파생차'
|
|
WHEN 'SAMPLE' THEN '시작차'
|
|
ELSE PPCI.PJT_TYPE
|
|
END PJT_TYPE
|
|
, PPCI.OEM_FACTORY
|
|
, PPCI.IS_DEL AS CONCEPT_IS_DEL_ORG
|
|
, PPCI.WRITER AS CONCEPT_WRITER_USER_ID
|
|
, (SELECT DEPT_NAME FROM USER_INFO WHERE USER_ID = PPCI.WRITER) AS CONCEPT_WRITER_DEPT_NAME
|
|
, (SELECT USER_NAME FROM USER_INFO WHERE USER_ID = PPCI.WRITER) AS CONCEPT_WRITER_USER_NAME
|
|
, PRPCP.PROD_OBJID
|
|
, (SELECT CODE_NAME FROM COMM_CODE WHERE OBJID = PRPCP.PROD_OBJID) AS PROD_NAME
|
|
, (SELECT CODE_ID FROM COMM_CODE WHERE OBJID = PRPCP.PROD_OBJID) AS PROD_CODE
|
|
, (SELECT PARENT_CODE_ID FROM COMM_CODE WHERE OBJID = PRPCP.PROD_OBJID) AS PRODUCT_GROUP_CODE
|
|
, (SELECT CODE_NAME FROM COMM_CODE WHERE CODE_ID = (SELECT PARENT_CODE_ID FROM COMM_CODE WHERE OBJID = PRPCP.PROD_OBJID)) AS PRODUCT_GROUP_NAME
|
|
, PRPCP.ESTIMATE_NO
|
|
, PPCI.ESTIMATE_REQ_DATE AS ESTIMATE_REQ_DATE_ORG
|
|
, TO_CHAR(PPCI.ESTIMATE_REQ_DATE, 'YYYY-MM-DD') AS ESTIMATE_REQ_DATE
|
|
, PPCI.ESTIMATE_SUBMIT_DATE AS ESTIMATE_SUBMIT_DATE_ORG
|
|
, TO_CHAR(PPCI.ESTIMATE_SUBMIT_DATE, 'YYYY-MM-DD') AS ESTIMATE_SUBMIT_DATE
|
|
, PPCI.WRITER AS ESTIMATE_PIC_USER_ID
|
|
, (SELECT DEPT_NAME FROM USER_INFO WHERE USER_ID = PPCI.WRITER) AS ESTIMATE_PIC_DEPT_NAME
|
|
, (SELECT USER_NAME FROM USER_INFO WHERE USER_ID = PPCI.WRITER) AS ESTIMATE_PIC_USER_NAME
|
|
, PPCI.YEARLY_AVG_PRODUCTION_CNT
|
|
, PPCI.TOTAL_PRODUCTION_CNT
|
|
, PRPCP.IS_DEL AS CONCEPT_PROD_IS_DEL_ORG
|
|
, (SELECT DEPT_NAME FROM USER_INFO WHERE USER_ID = PRPCP.WRITER) AS CONCEPT_PROD_WRITER_DEPT_NAME
|
|
, (SELECT USER_NAME FROM USER_INFO WHERE USER_ID = PRPCP.WRITER) AS CONCEPT_PROD_WRITER_USER_NAME
|
|
, CASE UPPER(PRPCP.STATUS)
|
|
WHEN 'CREATE' THEN '진행중'
|
|
WHEN 'COMPLETE' THEN '완료'
|
|
ELSE PRPCP.STATUS
|
|
END STATUS_NAME
|
|
, PRPCP.STATUS AS STATUS_ORG
|
|
, (SELECT USER_NAME || POSITION_NAME FROM USER_INFO WHERE USER_ID = PPCI.PM_ID) AS PM_INFO
|
|
FROM
|
|
PMS_REL_PJT_CONCEPT_PROD PRPCP,
|
|
PMS_PJT_CONCEPT_INFO PPCI
|
|
WHERE 1=1
|
|
AND PRPCP.TARGET_OBJID = PPCI.OBJID
|
|
)
|
|
</sql>
|
|
|
|
<!-- //내외작관리 목록 -->
|
|
<select id="externalWorkReviewList" parameterType="map" resultType="map">
|
|
SELECT
|
|
A.*
|
|
,ROW_NUMBER() OVER( PARTITION BY A.OBJID,A.PRODUCT_GROUP_CODE ORDER BY PROD_CODE) AS PROJECT_PRODUCT_PARTITION_NUM
|
|
,DENSE_RANK () OVER(ORDER BY A.OBJID) AS PROJECT_PARTITION_NUM
|
|
FROM(
|
|
SELECT
|
|
A.*
|
|
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = A.PRODUCT_GROUP_CODE AND O.PARENT_CODE_ID = #{PRODUCT_GROUP_CODE}) AS PRODUCT_GROUP_NAME
|
|
,(SELECT CODE_NAME FROM COMM_CODE WHERE PARENT_CODE_ID = #{OEM_FACTROY_CODE} AND OBJID = A.OEM_FACTORY) AS OEM_FACTORY_NAME
|
|
|
|
,EWRI.MOLD_DEV_CO_CNT
|
|
,EWRI.MOLD_DEV_NEW_CNT
|
|
,EWRI.PART_DEV_IH_CNT
|
|
,EWRI.PART_DEV_EX_CNT
|
|
,EWRI.DATA_CNT
|
|
FROM
|
|
<include refid="projectProductBase"/> A
|
|
LEFT JOIN (
|
|
SELECT
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
SUM(MOLD_DEV_CO_CNT) AS MOLD_DEV_CO_CNT,
|
|
SUM(MOLD_DEV_NEW_CNT) AS MOLD_DEV_NEW_CNT,
|
|
SUM(PART_DEV_IH_CNT) AS PART_DEV_IH_CNT,
|
|
SUM(PART_DEV_EX_CNT) AS PART_DEV_EX_CNT,
|
|
COUNT(1) AS DATA_CNT
|
|
FROM
|
|
(
|
|
SELECT
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
CASE
|
|
WHEN UPPER(MOLD_DEV_CODE) = 'CARRYOVER' THEN 1
|
|
ELSE 0
|
|
END MOLD_DEV_CO_CNT,
|
|
CASE
|
|
WHEN UPPER(MOLD_DEV_CODE) = 'NEW' THEN 1
|
|
ELSE 0
|
|
END MOLD_DEV_NEW_CNT,
|
|
CASE
|
|
WHEN UPPER(PART_DEV_CODE) = 'INHOUSE' THEN 1
|
|
ELSE 0
|
|
END PART_DEV_IH_CNT,
|
|
CASE
|
|
WHEN UPPER(PART_DEV_CODE) = 'EXTERNAL' THEN 1
|
|
ELSE 0
|
|
END PART_DEV_EX_CNT
|
|
FROM
|
|
EXTERNAL_WORK_REVIEW_INFO EWRI
|
|
WHERE
|
|
1 = 1
|
|
) EWRI
|
|
WHERE 1=1
|
|
GROUP BY
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID
|
|
)EWRI
|
|
ON A.OEM_OBJID = EWRI.OEM_OBJID::INTEGER
|
|
AND A.CAR_OBJID = EWRI.CAR_OBJID::INTEGER
|
|
AND A.PRODUCT_GROUP_CODE = EWRI.PRODUCT_GROUP_OBJID
|
|
AND A.PROD_CODE = EWRI.PRODUCT_OBJID
|
|
WHERE 1=1
|
|
<if test="search_customer != null and search_customer != ''">
|
|
AND A.OEM_OBJID = #{search_customer}::INTEGER
|
|
</if>
|
|
<if test="search_car_type != null and search_car_type != ''">
|
|
AND A.CAR_OBJID = #{search_car_type}::INTEGER
|
|
</if>
|
|
<if test="search_product_group != null and search_product_group != ''">
|
|
AND A.PRODUCT_GROUP_CODE = #{search_product_group}
|
|
</if>
|
|
<if test="search_product != null and search_product != ''">
|
|
AND A.PROD_CODE = #{search_product}
|
|
</if>
|
|
) A
|
|
</select>
|
|
|
|
<!-- //정전개 조회 쿼리 -->
|
|
<select id="structureAscendingList" parameterType="map" resultType="map">
|
|
WITH RECURSIVE VIEW_BOM(
|
|
OBJID,
|
|
PART_NO,
|
|
BOM_REPORT_OBJID,
|
|
PARENT_PART_NO,
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
LEV,
|
|
PATH,
|
|
PART_ARRAY,
|
|
CYCLE,
|
|
QTY,
|
|
REV,
|
|
EO_NO,
|
|
EO_ISSUE_DATE,
|
|
MATERIAL_NAME,
|
|
WEIGHT,
|
|
SIZE,
|
|
SURFACE_TREATMENT,
|
|
MOLD_DEV,
|
|
PART_OBJID
|
|
) AS (
|
|
SELECT
|
|
A.OBJID,
|
|
A.PART_NO,
|
|
A.BOM_REPORT_OBJID,
|
|
A.PARENT_PART_NO,
|
|
C.OEM_OBJID,
|
|
C.CAR_OBJID,
|
|
C.PRODUCT_GROUP_OBJID,
|
|
C.PRODUCT_OBJID,
|
|
1,
|
|
ARRAY[A.PART_NO::TEXT],
|
|
ARRAY[A.PART_NO] AS PART_ARRAY,
|
|
FALSE AS CYCLE,
|
|
B.QTY,
|
|
B.REVISION AS REV,
|
|
B.EO_NO,
|
|
B.EO_DATE AS EO_ISSUE_DATE,
|
|
(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = B.MATERIAL AND O.PARENT_CODE_ID = #{MATERIAL_CODE}) AS MATERIAL_NAME,
|
|
B.WEIGHT,
|
|
B.SIZE,
|
|
B.SURFACE_TREATMENT,
|
|
B.MOLD_DEV,
|
|
B.OBJID AS PART_OBJID
|
|
FROM
|
|
PART_BOM_QTY A,
|
|
<include refid="partMng.partMngBase"/> B,
|
|
PART_BOM_REPORT C
|
|
WHERE 1=1
|
|
AND C.OBJID = A.BOM_REPORT_OBJID
|
|
AND A.PART_NO = B.PART_NO
|
|
AND B.IS_LAST = '1'
|
|
AND (A.PARENT_PART_NO IS NULL OR A.PARENT_PART_NO = '')
|
|
<if test="search_oemObjId != null and !''.equals(search_oemObjId)">
|
|
AND C.OEM_OBJID = #{search_oemObjId}::NUMERIC
|
|
</if>
|
|
<if test="search_carObjId != null and !''.equals(search_carObjId)">
|
|
AND C.CAR_OBJID = #{search_carObjId}::NUMERIC
|
|
</if>
|
|
<if test="search_productObjId != null and !''.equals(search_productObjId)">
|
|
AND C.PRODUCT_OBJID = #{search_productObjId}
|
|
</if>
|
|
<if test="search_partNo != null and !''.equals(search_partNo)">
|
|
AND UPPER(A.PART_NO) LIKE UPPER('%${search_partNo}%')
|
|
</if>
|
|
<if test="search_partName != null and !''.equals(search_partName)">
|
|
AND UPPER(B.PART_NAME) LIKE UPPER('%${search_partName}%')
|
|
</if>
|
|
UNION ALL
|
|
|
|
SELECT
|
|
A.OBJID,
|
|
A.PART_NO,
|
|
A.BOM_REPORT_OBJID,
|
|
A.PARENT_PART_NO,
|
|
C.OEM_OBJID,
|
|
C.CAR_OBJID,
|
|
C.PRODUCT_GROUP_OBJID,
|
|
C.PRODUCT_OBJID,
|
|
LEV + 1,
|
|
PATH||A.PART_NO::TEXT,
|
|
D.PART_ARRAY,
|
|
A.PART_NO = ANY(PART_ARRAY) AS CYCLE,
|
|
B.QTY,
|
|
B.REVISION AS REV,
|
|
B.EO_NO,
|
|
B.EO_DATE AS EO_ISSUE_DATE,
|
|
(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = B.MATERIAL AND O.PARENT_CODE_ID = #{MATERIAL_CODE}) AS MATERIAL_NAME,
|
|
B.WEIGHT,
|
|
B.SIZE,
|
|
B.SURFACE_TREATMENT,
|
|
B.MOLD_DEV,
|
|
B.OBJID AS PART_OBJID
|
|
FROM
|
|
PART_BOM_QTY A,
|
|
<include refid="partMng.partMngBase"/> B,
|
|
PART_BOM_REPORT C,
|
|
VIEW_BOM D
|
|
WHERE 1=1
|
|
AND B.IS_LAST = '1'
|
|
AND C.OBJID = A.BOM_REPORT_OBJID
|
|
AND A.PART_NO = B.PART_NO
|
|
AND A.PARENT_PART_NO = D.PART_NO
|
|
AND D.BOM_REPORT_OBJID = A.BOM_REPORT_OBJID
|
|
)
|
|
SELECT
|
|
V.LEV AS LEVEL
|
|
,V.LEV
|
|
,(SELECT OBJID FROM VIEW_BOM VT WHERE V.BOM_REPORT_OBJID = VT.BOM_REPORT_OBJID AND VT.LEV = 1) AS SUB_ROOT_OBJID
|
|
,V.PART_NO LPAD_PART_NO
|
|
,(
|
|
SELECT
|
|
CASE
|
|
WHEN COUNT(*) > 0 THEN 0
|
|
ELSE 1
|
|
END LEAF
|
|
FROM VIEW_BOM VT
|
|
WHERE V.BOM_REPORT_OBJID = VT.BOM_REPORT_OBJID
|
|
AND V.PART_NO = VT.PARENT_PART_NO
|
|
) AS LEAF
|
|
,E.OBJID
|
|
,V.PART_NO
|
|
,(SELECT PART_NAME FROM PART_MNG WHERE PART_NO = V.PART_NO AND IS_LAST = 1::text) AS PART_NAME
|
|
,V.PARENT_PART_NO
|
|
,V.BOM_REPORT_OBJID
|
|
,V.OEM_OBJID
|
|
,V.CAR_OBJID
|
|
,V.PRODUCT_GROUP_OBJID
|
|
,V.PRODUCT_OBJID
|
|
,(SELECT COUNT(*) FROM VIEW_BOM VT WHERE V.BOM_REPORT_OBJID = VT.BOM_REPORT_OBJID AND V.PARENT_PART_NO = VT.PART_NO) AS SUB_PART_CNT
|
|
,(SELECT OBJID FROM VIEW_BOM VT WHERE V.BOM_REPORT_OBJID = VT.BOM_REPORT_OBJID AND VT.LEV = 1) AS ROOT_OBJID
|
|
,V.QTY
|
|
,V.REV AS REVISION
|
|
,V.REV
|
|
,V.EO_NO
|
|
,V.EO_ISSUE_DATE
|
|
,V.MATERIAL_NAME
|
|
,V.WEIGHT
|
|
,V.SIZE
|
|
,V.SURFACE_TREATMENT
|
|
,V.MOLD_DEV
|
|
,V.PART_OBJID
|
|
,V.MOLD_DEV AS MOLD_DEV_CODE
|
|
<!-- ,E.MOLD_DEV_CODE 별도의 금형개발 선택값이 아닌 파트에 지정된 금형개발 내용을 사용한다.-->
|
|
,E.MOLD_DEV_PARTNER_CODE
|
|
,CASE UPPER(V.MOLD_DEV)
|
|
WHEN 'CARRYOVER' THEN 'C/O'
|
|
WHEN 'NEW' THEN '신규'
|
|
ELSE ''
|
|
END MOLD_DEV_TITLE
|
|
,E.PART_DEV_CODE
|
|
,E.PART_DEV_PARTNER_CODE
|
|
,CASE UPPER(E.PART_DEV_CODE)
|
|
WHEN 'INHOUSE' THEN '내작'
|
|
WHEN 'EXTERNAL' THEN '외작'
|
|
ELSE ''
|
|
END PART_DEV_TITLE
|
|
FROM
|
|
VIEW_BOM V
|
|
LEFT JOIN EXTERNAL_WORK_REVIEW_INFO E
|
|
ON V.OEM_OBJID::TEXT = E.OEM_OBJID
|
|
AND V.CAR_OBJID::TEXT = E.CAR_OBJID
|
|
AND V.PRODUCT_GROUP_OBJID::TEXT = E.PRODUCT_GROUP_OBJID
|
|
AND V.PRODUCT_OBJID::TEXT = E.PRODUCT_OBJID
|
|
AND V.PART_NO = E.PART_NO
|
|
WHERE 1=1
|
|
|
|
<!-- 금형제작의뢰 등록 시 사용 -->
|
|
<if test="search_mold_dev_partner_code != null and search_mold_dev_partner_code != ''">
|
|
AND E.MOLD_DEV_PARTNER_CODE = #{search_mold_dev_partner_code}
|
|
</if>
|
|
|
|
ORDER BY
|
|
V.BOM_REPORT_OBJID,
|
|
PATH
|
|
</select>
|
|
|
|
<update id="saveExternalWorkReview" parameterType="map">
|
|
INSERT INTO EXTERNAL_WORK_REVIEW_INFO
|
|
(
|
|
OBJID
|
|
,PROJECT_OBJID
|
|
,BOM_REPORT_OBJID
|
|
,OEM_OBJID
|
|
,CAR_OBJID
|
|
,PRODUCT_GROUP_OBJID
|
|
,PRODUCT_OBJID
|
|
,PART_NO
|
|
,MOLD_DEV_CODE
|
|
,MOLD_DEV_PARTNER_CODE
|
|
,PART_DEV_CODE
|
|
,PART_DEV_PARTNER_CODE
|
|
,WRITER
|
|
,REGDATE
|
|
)
|
|
VALUES
|
|
(
|
|
#{OBJID}
|
|
,#{PROJECT_OBJID}
|
|
,#{BOM_REPORT_OBJID}
|
|
,#{OEM_OBJID}
|
|
,#{CAR_OBJID}
|
|
,#{PRODUCT_GROUP_OBJID}
|
|
,#{PRODUCT_OBJID}
|
|
,#{PART_NO}
|
|
,#{MOLD_DEV_CODE}
|
|
,#{MOLD_DEV_PARTNER_CODE}
|
|
,#{PART_DEV_CODE}
|
|
,#{PART_DEV_PARTNER_CODE}
|
|
,#{WRITER}
|
|
,NOW()
|
|
) ON CONFLICT (OBJID) DO
|
|
|
|
UPDATE
|
|
SET
|
|
PROJECT_OBJID = #{PROJECT_OBJID}
|
|
,BOM_REPORT_OBJID = #{BOM_REPORT_OBJID}
|
|
,OEM_OBJID = #{OEM_OBJID}
|
|
,CAR_OBJID = #{CAR_OBJID}
|
|
,PRODUCT_GROUP_OBJID = #{PRODUCT_GROUP_OBJID}
|
|
,PRODUCT_OBJID = #{PRODUCT_OBJID}
|
|
,PART_NO = #{PART_NO}
|
|
,MOLD_DEV_CODE = #{MOLD_DEV_CODE}
|
|
,MOLD_DEV_PARTNER_CODE = #{MOLD_DEV_PARTNER_CODE}
|
|
,PART_DEV_CODE = #{PART_DEV_CODE}
|
|
,PART_DEV_PARTNER_CODE = #{PART_DEV_PARTNER_CODE}
|
|
,WRITER = #{WRITER}
|
|
</update>
|
|
|
|
<select id="moldDevRequestList" parameterType="map" resultType="map">
|
|
SELECT
|
|
A.*
|
|
,ROW_NUMBER() OVER( PARTITION BY A.OBJID,A.PRODUCT_GROUP_CODE ORDER BY PROD_CODE) AS PROJECT_PRODUCT_PARTITION_NUM
|
|
,DENSE_RANK () OVER(ORDER BY A.OBJID) AS PROJECT_PARTITION_NUM
|
|
FROM(
|
|
SELECT
|
|
A.*
|
|
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = A.PRODUCT_GROUP_CODE AND O.PARENT_CODE_ID = #{PRODUCT_GROUP_CODE}) AS PRODUCT_GROUP_NAME
|
|
,(SELECT CODE_NAME FROM COMM_CODE WHERE PARENT_CODE_ID = #{OEM_FACTROY_CODE} AND OBJID = A.OEM_FACTORY) AS OEM_FACTORY_NAME
|
|
,MDRI.MOLD_DEV_PARTNER_CODE
|
|
,MDRI.MOLD_DEV_PARTNER_NAME
|
|
,MDRI.MOLD_DEV_REQUEST_OBJID
|
|
,MDRI.STATUS
|
|
,MDRI.STATUS_TITLE
|
|
,MDRI.REGDATE_TITLE
|
|
,MDRI.PRODUCTION_COMPLETION_DATE
|
|
,APP.APPR_STATUS
|
|
,APP.ROUTE_OBJID
|
|
,APP.APPROVAL_OBJID
|
|
FROM
|
|
<include refid="projectProductBase"/> A
|
|
INNER JOIN (
|
|
SELECT
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
MOLD_DEV_PARTNER_CODE
|
|
FROM
|
|
(
|
|
SELECT
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
MOLD_DEV_PARTNER_CODE
|
|
FROM
|
|
EXTERNAL_WORK_REVIEW_INFO EWRI
|
|
WHERE 1 = 1
|
|
AND MOLD_DEV_PARTNER_CODE IS NOT NULL
|
|
AND MOLD_DEV_PARTNER_CODE != ''
|
|
) EWRI
|
|
WHERE 1=1
|
|
GROUP BY
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
MOLD_DEV_PARTNER_CODE
|
|
)EWRI
|
|
ON A.OEM_OBJID = EWRI.OEM_OBJID::INTEGER
|
|
AND A.CAR_OBJID = EWRI.CAR_OBJID::INTEGER
|
|
AND A.PRODUCT_GROUP_CODE = EWRI.PRODUCT_GROUP_OBJID
|
|
AND A.PROD_CODE = EWRI.PRODUCT_OBJID
|
|
INNER JOIN (
|
|
SELECT
|
|
OBJID AS MOLD_DEV_REQUEST_OBJID,
|
|
PROJECT_OBJID,
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
TITLE,
|
|
RESIGN,
|
|
PRODUCT_SIZE,
|
|
PRODUCTION_CORPORATION,
|
|
PRODUCTION_COMPLETION_DATE,
|
|
ENGRAVE_APPLY,
|
|
ESTIMATE_PRICE,
|
|
PAYMENT_TYPE,
|
|
MOLD_PRODUCTION_MAIN_SPEC,
|
|
MOLD_DEV_PARTNER_CODE,
|
|
(SELECT SUPPLY_NAME FROM SUPPLY_MNG WHERE SUPPLY_CODE = MOLD_DEV_PARTNER_CODE) AS MOLD_DEV_PARTNER_NAME,
|
|
WRITER,
|
|
TO_CHAR(REGDATE,'YYYY-MM-DD') AS REGDATE_TITLE,
|
|
REGDATE,
|
|
TO_CHAR(EDITDATE,'YYYY-MM-DD') AS EDITDATE_TITLE,
|
|
EDITDATE,
|
|
STATUS,
|
|
CASE UPPER(STATUS)
|
|
WHEN 'CREATE' THEN '작성중'
|
|
WHEN 'APPROVALREQUEST' THEN '결재중'
|
|
WHEN 'REJECT' THEN '반려'
|
|
WHEN 'APPROVALCOMPLETE' THEN '결재완료'
|
|
WHEN 'SENDREQUEST' THEN '업체발송'
|
|
ELSE ''
|
|
END STATUS_TITLE
|
|
FROM
|
|
MOLD_DEV_REQUEST_INFO MDRI
|
|
) MDRI
|
|
ON A.OBJID = MDRI.PROJECT_OBJID::INTEGER
|
|
AND A.OEM_OBJID = MDRI.OEM_OBJID::INTEGER
|
|
AND A.CAR_OBJID = MDRI.CAR_OBJID::INTEGER
|
|
AND A.PRODUCT_GROUP_CODE = MDRI.PRODUCT_GROUP_OBJID
|
|
AND A.PROD_CODE = MDRI.PRODUCT_OBJID
|
|
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 ('MOLD_DEV_REQUEST')
|
|
) APP
|
|
ON MDRI.MOLD_DEV_REQUEST_OBJID::numeric = APP.TARGET_OBJID
|
|
WHERE 1=1
|
|
<if test="search_customer != null and search_customer != ''">
|
|
AND A.OEM_OBJID = #{search_customer}::INTEGER
|
|
</if>
|
|
<if test="search_car_type != null and search_car_type != ''">
|
|
AND A.CAR_OBJID = #{search_car_type}::INTEGER
|
|
</if>
|
|
<if test="search_product_group != null and search_product_group != ''">
|
|
AND A.PRODUCT_GROUP_CODE = #{search_product_group}
|
|
</if>
|
|
<if test="search_product != null and search_product != ''">
|
|
AND A.PROD_CODE = #{search_product}
|
|
</if>
|
|
) A
|
|
</select>
|
|
|
|
<!-- 금형제작의뢰 상세 내요을 가져온다. -->
|
|
<select id="moldDevRequestInfo" parameterType="map" resultType="map">
|
|
SELECT
|
|
OBJID,
|
|
PROJECT_OBJID,
|
|
(SELECT ESTIMATE_NO FROM PMS_REL_PJT_CONCEPT_PROD PRPCP WHERE 1=1 AND PRPCP.TARGET_OBJID::TEXT = MDRI.PROJECT_OBJID GROUP BY ESTIMATE_NO) AS PROJECT_NO,
|
|
OEM_OBJID,
|
|
(SELECT OEM_CODE FROM OEM_MNG WHERE OBJID = MDRI.OEM_OBJID::INTEGER) AS OEM_CODE,
|
|
CAR_OBJID,
|
|
(SELECT CAR_CODE FROM CAR_MNG WHERE OBJID = MDRI.CAR_OBJID::INTEGER) AS CAR_CODE,
|
|
PRODUCT_GROUP_OBJID,
|
|
(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = MDRI.PRODUCT_GROUP_OBJID AND O.PARENT_CODE_ID = #{PRODUCT_GROUP_CODE}) AS PRODUCT_GROUP_NAME,
|
|
PRODUCT_OBJID,
|
|
(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = MDRI.PRODUCT_OBJID AND O.PARENT_CODE_ID = MDRI.PRODUCT_GROUP_OBJID) AS PRODUCT_NAME,
|
|
TITLE,
|
|
RESIGN,
|
|
PRODUCT_SIZE,
|
|
PRODUCTION_CORPORATION,
|
|
PRODUCTION_COMPLETION_DATE,
|
|
ENGRAVE_APPLY,
|
|
ESTIMATE_PRICE,
|
|
PAYMENT_TYPE,
|
|
MOLD_PRODUCTION_MAIN_SPEC,
|
|
MOLD_DEV_PARTNER_CODE,
|
|
(SELECT SUPPLY_NAME FROM SUPPLY_MNG WHERE SUPPLY_CODE = MOLD_DEV_PARTNER_CODE) AS MOLD_DEV_PARTNER_NAME,
|
|
WRITER,
|
|
REGDATE,
|
|
TO_CHAR(MDRI.REGDATE,'YYYY-MM-DD') AS REGDATE_TITLE,
|
|
(SELECT DEPT_NAME||' '||USER_NAME FROM USER_INFO WHERE USER_ID = MDRI.WRITER) AS WRITER_TITLE,
|
|
EDITDATE,
|
|
STATUS
|
|
FROM
|
|
MOLD_DEV_REQUEST_INFO MDRI
|
|
WHERE OBJID = #{OBJID}
|
|
</select>
|
|
|
|
<update id="saveMoldDevRequestInfo" parameterType="map">
|
|
INSERT INTO MOLD_DEV_REQUEST_INFO
|
|
(
|
|
OBJID,
|
|
PROJECT_OBJID,
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
TITLE,
|
|
RESIGN,
|
|
PRODUCT_SIZE,
|
|
PRODUCTION_CORPORATION,
|
|
PRODUCTION_COMPLETION_DATE,
|
|
ENGRAVE_APPLY,
|
|
ESTIMATE_PRICE,
|
|
PAYMENT_TYPE,
|
|
MOLD_PRODUCTION_MAIN_SPEC,
|
|
MOLD_DEV_PARTNER_CODE,
|
|
WRITER,
|
|
REGDATE,
|
|
STATUS
|
|
)
|
|
VALUES
|
|
(
|
|
#{OBJID},
|
|
#{PROJECT_OBJID},
|
|
#{OEM_OBJID},
|
|
#{CAR_OBJID},
|
|
#{PRODUCT_GROUP_OBJID},
|
|
#{PRODUCT_OBJID},
|
|
#{TITLE},
|
|
#{RESIGN},
|
|
#{PRODUCT_SIZE},
|
|
#{PRODUCTION_CORPORATION},
|
|
#{PRODUCTION_COMPLETION_DATE},
|
|
#{ENGRAVE_APPLY},
|
|
#{ESTIMATE_PRICE},
|
|
#{PAYMENT_TYPE},
|
|
#{MOLD_PRODUCTION_MAIN_SPEC},
|
|
#{MOLD_DEV_PARTNER_CODE},
|
|
#{WRITER},
|
|
NOW(),
|
|
'create'
|
|
) ON CONFLICT (OBJID) DO
|
|
|
|
UPDATE
|
|
SET
|
|
PROJECT_OBJID = #{PROJECT_OBJID},
|
|
OEM_OBJID = #{OEM_OBJID},
|
|
CAR_OBJID = #{CAR_OBJID},
|
|
PRODUCT_GROUP_OBJID = #{PRODUCT_GROUP_OBJID},
|
|
PRODUCT_OBJID = #{PRODUCT_OBJID},
|
|
TITLE = #{TITLE},
|
|
RESIGN = #{RESIGN},
|
|
PRODUCT_SIZE = #{PRODUCT_SIZE},
|
|
PRODUCTION_CORPORATION = #{PRODUCTION_CORPORATION},
|
|
PRODUCTION_COMPLETION_DATE = #{PRODUCTION_COMPLETION_DATE},
|
|
ENGRAVE_APPLY = #{ENGRAVE_APPLY},
|
|
ESTIMATE_PRICE = #{ESTIMATE_PRICE},
|
|
PAYMENT_TYPE = #{PAYMENT_TYPE},
|
|
MOLD_PRODUCTION_MAIN_SPEC = #{MOLD_PRODUCTION_MAIN_SPEC},
|
|
MOLD_DEV_PARTNER_CODE = #{MOLD_DEV_PARTNER_CODE},
|
|
WRITER = #{WRITER},
|
|
EDITDATE = NOW(),
|
|
STATUS = #{STATUS}
|
|
</update>
|
|
|
|
<update id="changeMoldDevRequestStatus" parameterType="map">
|
|
UPDATE MOLD_DEV_REQUEST_INFO SET
|
|
STATUS = #{STATUS}
|
|
WHERE OBJID = #{OBJID}
|
|
</update>
|
|
|
|
<!-- //파일목록 조회 -->
|
|
<select id="getPartFileList" resultType="map" parameterType="map">
|
|
SELECT OBJID
|
|
, TARGET_OBJID
|
|
, (SELECT PART_NO FROM PART_MNG A WHERE OBJID = ${TARGET_OBJID}) PART_NO
|
|
, (SELECT REVISION FROM PART_MNG A WHERE OBJID = ${TARGET_OBJID}) REV
|
|
, SAVED_FILE_NAME
|
|
, REAL_FILE_NAME
|
|
, DOC_TYPE
|
|
, DOC_TYPE_NAME
|
|
, FILE_SIZE
|
|
, FILE_EXT
|
|
, REPLACE(FILE_PATH, '\', '\\') AS FILE_PATH
|
|
, WRITER
|
|
, TO_CHAR(REGDATE, 'YYYY-MM-DD') AS REGDATE
|
|
, REGDATE AS REGDATE_ORG
|
|
, STATUS
|
|
FROM ATTACH_FILE_INFO
|
|
WHERE 1=1
|
|
AND TARGET_OBJID = ${TARGET_OBJID}
|
|
<if test="TARGET_DOC_TYPE != null and !''.equals(TARGET_DOC_TYPE)">
|
|
AND DOC_TYPE = #{TARGET_DOC_TYPE}
|
|
</if>
|
|
AND STATUS = 'Active'
|
|
ORDER BY REGDATE_ORG DESC
|
|
</select>
|
|
|
|
<!-- EO 수정이력 대상 영업 목록 조회 -->
|
|
<select id="eoChangeHistoryList" parameterType="map" resultType="map">
|
|
SELECT
|
|
A.*
|
|
,ROW_NUMBER() OVER( PARTITION BY A.OBJID,A.PRODUCT_GROUP_CODE ORDER BY PROD_CODE) AS PROJECT_PRODUCT_PARTITION_NUM
|
|
,DENSE_RANK () OVER(ORDER BY A.OBJID) AS PROJECT_PARTITION_NUM
|
|
FROM(
|
|
SELECT
|
|
A.*
|
|
,(SELECT O.CODE_NAME FROM COMM_CODE O WHERE O.CODE_ID = A.PRODUCT_GROUP_CODE AND O.PARENT_CODE_ID = #{PRODUCT_GROUP_CODE}) AS PRODUCT_GROUP_NAME
|
|
,(SELECT CODE_NAME FROM COMM_CODE WHERE PARENT_CODE_ID = #{OEM_FACTROY_CODE} AND OBJID = A.OEM_FACTORY) AS OEM_FACTORY_NAME
|
|
|
|
,ECH.RECEIPT_CNT
|
|
,ECH.MEASURE_CNT
|
|
,ECH.MEASURE_RATIO
|
|
FROM
|
|
<include refid="projectProductBase"/> A
|
|
LEFT JOIN (
|
|
SELECT
|
|
PROJECT_OBJID,
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
SUM(RECEIPT_CNT) AS RECEIPT_CNT,
|
|
SUM(MEASURE_CNT) AS MEASURE_CNT,
|
|
ROUND(100.0 * SUM(MEASURE_CNT) / SUM(RECEIPT_CNT))||' %' AS MEASURE_RATIO
|
|
FROM
|
|
(
|
|
SELECT
|
|
OBJID,
|
|
PROJECT_OBJID,
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
PART_OBJID,
|
|
PART_NO,
|
|
EO_NO,
|
|
EO_PUBLISHED_DATE,
|
|
EO_APPLY_DATE,
|
|
EO_STEP,
|
|
CHANGE_CONTENTS,
|
|
MEASURE_TYPE,
|
|
MEASURE_DATE,
|
|
CVT,
|
|
SET,
|
|
PARTNER_CODE,
|
|
OEM_ATTRITION_RATE,
|
|
MY_ATTRITION_RATE,
|
|
PARTNER_ATTRITION_RATE,
|
|
PARTNER_ESTIMATE_COST,
|
|
MY_COST,
|
|
OEM_CONTRIBUTION_AMOUNT,
|
|
MY_CONTRIBUTION_AMOUNT,
|
|
PARTNER_CONTRIBUTION_AMOUNT,
|
|
STATUS,
|
|
WRITER,
|
|
REGDATE,
|
|
1 AS RECEIPT_CNT,
|
|
CASE
|
|
WHEN MEASURE_DATE IS NOT NULL AND MEASURE_DATE != '' THEN 1
|
|
ELSE 0
|
|
END MEASURE_CNT
|
|
FROM
|
|
EO_CHANGE_HISTORY ECH
|
|
) ECH
|
|
WHERE 1=1
|
|
GROUP BY
|
|
PROJECT_OBJID,
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID
|
|
)ECH
|
|
ON A.OBJID = ECH.PROJECT_OBJID::INTEGER
|
|
and A.OEM_OBJID = ECH.OEM_OBJID::INTEGER
|
|
AND A.CAR_OBJID = ECH.CAR_OBJID::INTEGER
|
|
AND A.PRODUCT_GROUP_CODE = ECH.PRODUCT_GROUP_OBJID
|
|
AND A.PROD_CODE = ECH.PRODUCT_OBJID
|
|
WHERE 1=1
|
|
<if test="search_customer != null and search_customer != ''">
|
|
AND A.OEM_OBJID = #{search_customer}::INTEGER
|
|
</if>
|
|
<if test="search_car_type != null and search_car_type != ''">
|
|
AND A.CAR_OBJID = #{search_car_type}::INTEGER
|
|
</if>
|
|
<if test="search_product_group != null and search_product_group != ''">
|
|
AND A.PRODUCT_GROUP_CODE = #{search_product_group}
|
|
</if>
|
|
<if test="search_product != null and search_product != ''">
|
|
AND A.PROD_CODE = #{search_product}
|
|
</if>
|
|
) A
|
|
</select>
|
|
|
|
<!-- EO 수정이력 대상에 연결된 Part 목록 조회 -->
|
|
<select id="eoChangeHistoryPartList" resultType="map" parameterType="map">
|
|
SELECT
|
|
OBJID,
|
|
PROJECT_OBJID,
|
|
OEM_OBJID,
|
|
(SELECT OEM_CODE FROM OEM_MNG WHERE OBJID = OEM_OBJID::INTEGER) AS OEM_CODE,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
PART_OBJID,
|
|
PART_NO,
|
|
EO_NO,
|
|
EO_PUBLISHED_DATE,
|
|
EO_APPLY_DATE,
|
|
EO_STEP,
|
|
CHANGE_CONTENTS,
|
|
MEASURE_TYPE,
|
|
MEASURE_DATE,
|
|
CVT,
|
|
SET,
|
|
PARTNER_CODE,
|
|
OEM_ATTRITION_RATE,
|
|
MY_ATTRITION_RATE,
|
|
PARTNER_ATTRITION_RATE,
|
|
PARTNER_ESTIMATE_COST,
|
|
MY_COST,
|
|
OEM_CONTRIBUTION_AMOUNT,
|
|
MY_CONTRIBUTION_AMOUNT,
|
|
PARTNER_CONTRIBUTION_AMOUNT,
|
|
STATUS,
|
|
WRITER,
|
|
REGDATE
|
|
FROM
|
|
EO_CHANGE_HISTORY ECH
|
|
WHERE PROJECT_OBJID = #{search_projectObjId}
|
|
AND PRODUCT_OBJID = #{search_productObjId}
|
|
ORDER BY REGDATE DESC
|
|
</select>
|
|
|
|
<!-- EO 수정이력 대상이 되는 프로젝트의 상세 정보를 가져온다. -->
|
|
<select id="eoChangeHistoryTargetProjectInfo" resultType="map" parameterType="map">
|
|
SELECT
|
|
A.*
|
|
FROM
|
|
<include refid="projectProductBase"/> A
|
|
WHERE A.OBJID = #{search_projectObjId}::INTEGER
|
|
AND A.PROD_CODE = #{search_productObjId}
|
|
</select>
|
|
|
|
<!-- 해당 프로젝트에 연결 대상이 되는 Part의 목록을 가져온다. -->
|
|
<select id="eoChangeHistoryTargetPartList" resultType="map" parameterType="map">
|
|
SELECT
|
|
A.*,
|
|
PM.*,
|
|
PM.OBJID AS PART_OBJID
|
|
FROM
|
|
PART_MNG PM
|
|
INNER JOIN <include refid="projectProductBase"/> A
|
|
ON PM.CUSTOMER::INTEGER = A.OEM_OBJID
|
|
AND PM.CAR_TYPE::INTEGER = A.CAR_OBJID
|
|
AND PM.PRODUCT_GROUP = A.PRODUCT_GROUP_CODE
|
|
AND PM.PRODUCT = A.PROD_CODE
|
|
WHERE A.OBJID = #{search_projectObjId}::INTEGER
|
|
AND A.PROD_CODE = #{search_productObjId}
|
|
</select>
|
|
|
|
<update id="saveEOChangeHistoryPart" parameterType="map">
|
|
INSERT INTO EO_CHANGE_HISTORY
|
|
(
|
|
OBJID,
|
|
PROJECT_OBJID,
|
|
OEM_OBJID,
|
|
CAR_OBJID,
|
|
PRODUCT_GROUP_OBJID,
|
|
PRODUCT_OBJID,
|
|
PART_OBJID,
|
|
PART_NO,
|
|
EO_NO,
|
|
EO_PUBLISHED_DATE,
|
|
EO_APPLY_DATE,
|
|
EO_STEP,
|
|
CHANGE_CONTENTS,
|
|
MEASURE_TYPE,
|
|
MEASURE_DATE,
|
|
CVT,
|
|
SET,
|
|
PARTNER_CODE,
|
|
OEM_ATTRITION_RATE,
|
|
MY_ATTRITION_RATE,
|
|
PARTNER_ATTRITION_RATE,
|
|
PARTNER_ESTIMATE_COST,
|
|
MY_COST,
|
|
OEM_CONTRIBUTION_AMOUNT,
|
|
MY_CONTRIBUTION_AMOUNT,
|
|
PARTNER_CONTRIBUTION_AMOUNT,
|
|
STATUS,
|
|
WRITER,
|
|
REGDATE
|
|
)values(
|
|
#{OBJID}::INTEGER,
|
|
#{PROJECT_OBJID},
|
|
#{OEM_OBJID},
|
|
#{CAR_OBJID},
|
|
#{PRODUCT_GROUP_OBJID},
|
|
#{PRODUCT_OBJID},
|
|
#{PART_OBJID},
|
|
#{PART_NO},
|
|
#{EO_NO},
|
|
#{EO_PUBLISHED_DATE},
|
|
#{EO_APPLY_DATE},
|
|
#{EO_STEP},
|
|
#{CHANGE_CONTENTS},
|
|
#{MEASURE_TYPE},
|
|
#{MEASURE_DATE},
|
|
#{CVT},
|
|
#{SET},
|
|
#{PARTNER_CODE},
|
|
#{OEM_ATTRITION_RATE},
|
|
#{MY_ATTRITION_RATE},
|
|
#{PARTNER_ATTRITION_RATE},
|
|
#{PARTNER_ESTIMATE_COST},
|
|
#{MY_COST},
|
|
#{OEM_CONTRIBUTION_AMOUNT},
|
|
#{MY_CONTRIBUTION_AMOUNT},
|
|
#{PARTNER_CONTRIBUTION_AMOUNT},
|
|
#{STATUS},
|
|
#{WRITER},
|
|
NOW()
|
|
)ON CONFLICT (OBJID) DO
|
|
UPDATE
|
|
SET
|
|
PROJECT_OBJID = #{PROJECT_OBJID},
|
|
OEM_OBJID = #{OEM_OBJID},
|
|
CAR_OBJID = #{CAR_OBJID},
|
|
PRODUCT_GROUP_OBJID = #{PRODUCT_GROUP_OBJID},
|
|
PRODUCT_OBJID = #{PRODUCT_OBJID},
|
|
PART_OBJID = #{PART_OBJID},
|
|
PART_NO = #{PART_NO},
|
|
EO_NO = #{EO_NO},
|
|
EO_PUBLISHED_DATE = #{EO_PUBLISHED_DATE},
|
|
EO_APPLY_DATE = #{EO_APPLY_DATE},
|
|
EO_STEP = #{EO_STEP},
|
|
CHANGE_CONTENTS = #{CHANGE_CONTENTS},
|
|
MEASURE_TYPE = #{MEASURE_TYPE},
|
|
MEASURE_DATE = #{MEASURE_DATE},
|
|
CVT = #{CVT},
|
|
SET = #{SET},
|
|
PARTNER_CODE = #{PARTNER_CODE},
|
|
OEM_ATTRITION_RATE = #{OEM_ATTRITION_RATE},
|
|
MY_ATTRITION_RATE = #{MY_ATTRITION_RATE},
|
|
PARTNER_ATTRITION_RATE = #{PARTNER_ATTRITION_RATE},
|
|
PARTNER_ESTIMATE_COST = #{PARTNER_ESTIMATE_COST},
|
|
MY_COST = #{MY_COST},
|
|
OEM_CONTRIBUTION_AMOUNT = #{OEM_CONTRIBUTION_AMOUNT},
|
|
MY_CONTRIBUTION_AMOUNT = #{MY_CONTRIBUTION_AMOUNT},
|
|
PARTNER_CONTRIBUTION_AMOUNT = #{PARTNER_CONTRIBUTION_AMOUNT},
|
|
STATUS = #{STATUS},
|
|
WRITER = #{WRITER}
|
|
</update>
|
|
<!-- hwangeuidon end********************************************************************************************************** -->
|
|
|
|
</mapper>
|