##全部,根据finishTime判断代办,已办
DROP view vw_flow_all;
CREATE VIEW vw_flow_all AS (
	SELECT
		RES.ID_ AS procInsId,
		DEF.DEPLOYMENT_ID_ AS deployId,
		RES.START_TIME_ AS createTime,
		RES.END_TIME_ AS finishTime,
		CASE
	WHEN RES.END_TIME_ IS NULL THEN
		TIMESTAMPDIFF(
			MINUTE,
			RES.START_TIME_,
			DATE_FORMAT(NOW(), '%Y-%m-%d %H:%i:%S')
		)
	ELSE
		TIMESTAMPDIFF(
			MINUTE,
			RES.START_TIME_,
			RES.END_TIME_
		)
	END AS duration,
	DEF.NAME_ AS procDefName,
	DEF.VERSION_ AS procDefVersion,
	DEF.CATEGORY_ AS category,
	DEF.KEY_ AS procDefKey,
	v1.TEXT_ AS startUserId,
	v2.TEXT_ AS startUserName,
	v3.TEXT_ AS startDeptName,
	v4.TEXT_ AS startComId,
	v5.TEXT_ AS startComName,
	v6.TEXT_ AS startProId,
	v7.TEXT_ AS startProName,
	v8.TEXT_ AS businessKey,
	RES.PROC_INST_ID_,
	IFNULL(hr.ID_,ht.taskId) as taskId,
	IFNULL(hr.NAME_,ht.taskName) as taskName,
	IF(hr.ID_ IS NULL, ht.assigneeId, tu.user_id) as assigneeId,
	IF(hr.ID_ IS NULL, ht.assigneeName, tu.nick_name) as assigneeName,
	IF(hr.ID_ IS NULL, ht.assigneeDeptName, td.dept_name) as assigneeDeptName,
	IF(hr.ID_ IS NULL, ht.taskComType, 0) as taskComType
FROM
	ACT_HI_PROCINST RES
LEFT JOIN ACT_RE_PROCDEF DEF ON RES.PROC_DEF_ID_ = DEF.ID_
LEFT JOIN act_hi_varinst v1 ON v1.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v1.NAME_ = 'INITIATOR'
LEFT JOIN act_hi_varinst v2 ON v2.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v2.NAME_ = 'userName'
LEFT JOIN act_hi_varinst v3 ON v3.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v3.NAME_ = 'userDeptName'
LEFT JOIN act_hi_varinst v4 ON v4.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v4.NAME_ = 'comId'
LEFT JOIN act_hi_varinst v5 ON v5.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v5.NAME_ = 'comName'
LEFT JOIN act_hi_varinst v6 ON v6.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v6.NAME_ = 'proId'
LEFT JOIN act_hi_varinst v7 ON v7.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v7.NAME_ = 'proName'
LEFT JOIN act_hi_varinst v8 ON v8.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v8.NAME_ = 'businessKey'
LEFT JOIN act_ru_task hr ON hr.PROC_INST_ID_ = RES.PROC_INST_ID_
LEFT JOIN act_ru_actinst ra ON ra.TASK_ID_ = hr.ID_ AND ra.PROC_INST_ID_ = RES.PROC_INST_ID_
LEFT JOIN sys_user tu ON tu.user_id = ra.ASSIGNEE_
LEFT JOIN sys_dept td ON td.dept_id = tu.dept_id
LEFT JOIN (
	SELECT
		ht.ID_ AS taskId,
		ht.NAME_ AS taskName,
		tu.user_id AS assigneeId,
		tu.nick_name AS assigneeName,
		td.dept_name AS assigneeDeptName,
		ht.PROC_INST_ID_,
		ahc.TYPE_ as taskComType
	FROM
		act_hi_taskinst ht
	LEFT JOIN sys_user tu ON tu.user_id = ht.ASSIGNEE_
	LEFT JOIN sys_dept td ON td.dept_id = tu.dept_id
	left join act_hi_comment ahc on ahc.TASK_ID_ = ht.ID_ AND ahc.PROC_INST_ID_ is not NULL
	WHERE
		ht.ID_ IN (
			SELECT
				MAX(ID_)
			FROM
				act_hi_taskinst
			GROUP BY
				PROC_INST_ID_
		)
	GROUP BY ht.PROC_INST_ID_
) ht ON ht.PROC_INST_ID_ = RES.PROC_INST_ID_
)

##待办
DROP view vw_flow_await;
CREATE VIEW vw_flow_await AS (
SELECT
	RES.ID_ AS taskId,
	RES.NAME_ AS taskName,
	re.ID_ AS procInsId,
	DEF.DEPLOYMENT_ID_ AS deployId,
	DATE_FORMAT(re.START_TIME_, '%Y-%m-%d %H:%i:%S') AS createTime,
	TIMESTAMPDIFF(
		MINUTE,
		re.START_TIME_,
		DATE_FORMAT(NOW(), '%Y-%m-%d %H:%i:%S')
	) AS duration,
	DEF.NAME_ AS procDefName,
	DEF.VERSION_ AS procDefVersion,
	DEF.CATEGORY_ AS category,
	DEF.KEY_ AS procDefKey,
	v1.TEXT_ AS startUserId,
	v2.TEXT_ AS startUserName,
	v3.TEXT_ AS startDeptName,
	v4.TEXT_ AS startComId,
	v5.TEXT_ AS startComName,
	v6.TEXT_ AS startProId,
	v7.TEXT_ AS startProName,
	v8.TEXT_ AS businessKey,
	RES.SUSPENSION_STATE_,
	RES.ASSIGNEE_,
	LINK.USER_ID_,
	LINK.GROUP_ID_
FROM
	ACT_RU_TASK RES
LEFT JOIN act_ru_execution re ON re.PARENT_ID_ IS NULL AND re.PROC_INST_ID_ = RES.PROC_INST_ID_
LEFT OUTER JOIN ACT_RE_PROCDEF DEF ON re.PROC_DEF_ID_ = DEF.ID_
LEFT JOIN act_hi_varinst v1 ON v1.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v1.NAME_ = 'INITIATOR'
LEFT JOIN act_hi_varinst v2 ON v2.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v2.NAME_ = 'userName'
LEFT JOIN act_hi_varinst v3 ON v3.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v3.NAME_ = 'userDeptName'
LEFT JOIN act_hi_varinst v4 ON v4.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v4.NAME_ = 'comId'
LEFT JOIN act_hi_varinst v5 ON v5.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v5.NAME_ = 'comName'
LEFT JOIN act_hi_varinst v6 ON v6.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v6.NAME_ = 'proId'
LEFT JOIN act_hi_varinst v7 ON v7.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v7.NAME_ = 'proName'
LEFT JOIN act_hi_varinst v8 ON v8.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v8.NAME_ = 'businessKey'
LEFT JOIN ACT_RU_IDENTITYLINK LINK on LINK.TASK_ID_ = RES.ID_ AND LINK.TYPE_ = 'candidate'
WHERE
	RES.SUSPENSION_STATE_ = 1)
##下面是当前登录人代办查询条件
--  AND (
-- 	RES.ASSIGNEE_ = 1
-- 	OR (
-- 		RES.ASSIGNEE_ IS NULL
-- 		AND EXISTS (
-- 			SELECT
-- 				LINK.ID_
-- 			FROM
-- 				ACT_RU_IDENTITYLINK LINK
-- 			WHERE
-- 				LINK.TASK_ID_ = RES.ID_
-- 			AND LINK.TYPE_ = 'candidate'
-- 			AND (
-- 				LINK.USER_ID_ = 1
-- 				OR (
-- 					LINK.GROUP_ID_ IN (1, 42, 45, 46)
-- 				)
-- 			)
-- 		)
-- 	)
-- )

##审批意见
DROP view vw_flow_comment;
CREATE VIEW vw_flow_comment AS (
SELECT
	hc.ID_ AS commentId,
	hc.TYPE_ AS commentType,
	ht.ID_ AS taskId,
	ht.NAME_ AS taskName,
	ht.REV_ AS rev,
	CASE
WHEN hc.TYPE_ = 1 and ht.NAME_ !='提交申请' THEN
	'通过'
WHEN hc.TYPE_ = 2 THEN
	'退回'
WHEN hc.TYPE_ = 3 THEN
	'驳回'
WHEN hc.TYPE_ = 4 THEN
	'委派'
WHEN hc.TYPE_ = 5 THEN
	'转办'
WHEN hc.TYPE_ = 6 THEN
	'终止'
WHEN hc.TYPE_ = 7 THEN
	'撤回'
END AS commentResult,
 ht.PROC_INST_ID_ AS procInstId,
 ht.TASK_DEF_KEY_ AS taskDefKey,
 ht.EXECUTION_ID_ AS executionId,
 ht.DELETE_REASON_ AS deleteReason,
 DATE_FORMAT(
	ht.START_TIME_,
	'%Y-%m-%d %H:%i:%S'
) AS startTime,
 DATE_FORMAT(
	ht.END_TIME_,
	'%Y-%m-%d %H:%i:%S'
) AS endTime,
 ht.DURATION_ AS duration,
 hc.MESSAGE_ AS message,
 ru.nick_name AS assigneeName,
 IF(ru.dept_id IS NOT NULL, rd.dept_name, ru.remark) as deptName,
 sr.role_name as candidate
FROM
	act_hi_taskinst ht
LEFT JOIN act_hi_comment hc ON hc.TASK_ID_ = ht.ID_ or (hc.TASK_ID_ is null and hc.PROC_INST_ID_ = ht.PROC_INST_ID_)
LEFT JOIN act_hi_identitylink hi on hi.TASK_ID_ = ht.ID_ and hi.TYPE_ = 'candidate'
left JOIN sys_role sr on sr.role_id = hi.group_Id_
LEFT JOIN sys_user ru ON ru.user_id = ht.ASSIGNEE_
LEFT JOIN sys_dept rd ON rd.dept_id = ru.dept_id
where hc.TYPE_ is null or hc.TYPE_!='event')

##已办
DROP view vw_flow_finished;
CREATE VIEW vw_flow_finished AS (
SELECT
	RES.ID_ AS taskId,
	RES.NAME_ AS taskName,
	RES.PROC_INST_ID_ AS procInsId,
	pd.DEPLOYMENT_ID_ as deployId,
	DATE_FORMAT(RES.START_TIME_, '%Y-%m-%d %H:%i:%S') AS createTime,
	DATE_FORMAT(RES.END_TIME_, '%Y-%m-%d %H:%i:%S') AS endTime,
	TIMESTAMPDIFF(
		MINUTE,
		res.START_TIME_,
		RES.END_TIME_
	) AS duration,
DEF.END_TIME_ as finishTime,
	pd.NAME_ AS procDefName,
	pd.CATEGORY_ AS category,
	pd.KEY_ AS procDefKey,
	v1.TEXT_ AS startUserId,
	v2.TEXT_ AS startUserName,
	v3.TEXT_ AS startDeptName,
	v4.TEXT_ AS startComId,
	v5.TEXT_ AS startComName,
	v6.TEXT_ AS startProId,
	v7.TEXT_ AS startProName,
	v8.TEXT_ AS businessKey,
	RES.ASSIGNEE_,
	ahc.TYPE_ as taskComType
FROM
	act_hi_taskinst RES
LEFT OUTER JOIN act_hi_procinst DEF ON RES.PROC_INST_ID_ = DEF.PROC_INST_ID_
LEFT OUTER join act_re_procdef pd on RES.PROC_DEF_ID_ = pd.ID_
LEFT JOIN act_hi_varinst v1 ON v1.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v1.NAME_ = 'INITIATOR'
LEFT JOIN act_hi_varinst v2 ON v2.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v2.NAME_ = 'userName'
LEFT JOIN act_hi_varinst v3 ON v3.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v3.NAME_ = 'userDeptName'
LEFT JOIN act_hi_varinst v4 ON v4.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v4.NAME_ = 'comId'
LEFT JOIN act_hi_varinst v5 ON v5.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v5.NAME_ = 'comName'
LEFT JOIN act_hi_varinst v6 ON v6.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v6.NAME_ = 'proId'
LEFT JOIN act_hi_varinst v7 ON v7.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v7.NAME_ = 'proName'
LEFT JOIN act_hi_varinst v8 ON v8.PROC_INST_ID_ = RES.PROC_INST_ID_ AND v8.NAME_ = 'businessKey'
left join act_hi_comment ahc on ahc.TASK_ID_ = RES.ID_ AND ahc.PROC_INST_ID_ is not NULL
WHERE
	RES.ASSIGNEE_ is not null and RES.END_TIME_ is not null)