You can not select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
174 lines
6.8 KiB
174 lines
6.8 KiB
<?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="com.ccic.safeliab.dao.ExamStatisticsMapper"> |
|
<select id="getQuestionCount" resultType="java.lang.Integer"> |
|
select count(1) from ex_question_categories |
|
where status = 1 |
|
and is_deleted = 0 |
|
</select> |
|
<select id="getPaperCount" resultType="java.lang.Integer"> |
|
select count(1) from ex_exam_papers |
|
where paper_status = 1 |
|
and is_deleted = 0 |
|
</select> |
|
<select id="getExamCount" resultType="java.lang.Integer"> |
|
select count(1) from ex_exam_info |
|
where status = 1 |
|
and publish_status = 1 |
|
and is_deleted = 0 |
|
</select> |
|
<select id="getIndustryDimensionData" resultType="java.util.Map"> |
|
<![CDATA[ |
|
SELECT |
|
COUNT ( q.ID ) AS "value", |
|
( ind.industry_name || ': ' || COUNT ( q.ID ) || ' 条' ) AS "name" |
|
FROM |
|
tbl_industry ind |
|
LEFT JOIN ex_question_categories q ON q.industry_id = ind.industry_id |
|
AND q.is_deleted = 0 |
|
AND q.status = 1 |
|
WHERE |
|
ind.status = 1 |
|
GROUP BY |
|
ind.industry_id, |
|
ind.industry_name |
|
ORDER BY |
|
ind.industry_id |
|
]]> |
|
</select> |
|
<select id="getAqServiceDimensionData" resultType="java.util.Map"> |
|
<![CDATA[ |
|
SELECT |
|
COUNT ( q.ID ) AS "value", |
|
( dict.dict_value || ': ' || COUNT ( q.ID ) || ' 条' ) AS "name" |
|
FROM |
|
ex_dict dict |
|
LEFT JOIN ex_question_categories q ON q.service_type_id = dict.dict_key |
|
AND q.is_deleted = 0 |
|
AND q.status = 1 |
|
WHERE |
|
dict.code = 'serviceTypeDict' |
|
AND dict.is_deleted = 0 |
|
AND dict.parent_id <> 0 |
|
GROUP BY |
|
dict.dict_key, |
|
dict.dict_value |
|
ORDER BY |
|
dict.dict_key |
|
]]> |
|
</select> |
|
<select id="getExamTableData" resultType="java.util.Map"> |
|
<![CDATA[ |
|
-- 定义 CTE exam_Count,统计符合条件的考试数量 |
|
WITH exam_Count AS ( |
|
SELECT COUNT(1) AS "count" |
|
FROM ex_exam_info |
|
WHERE status = 1 |
|
AND publish_status = 1 |
|
AND is_deleted = 0 |
|
), |
|
-- 定义 CTE scores,计算每个考试记录的得分比例和用时 |
|
scores AS ( |
|
SELECT |
|
score.total_score / papers.total_score AS score, |
|
score.exam_time_spent AS time_spent |
|
FROM |
|
ex_exam_scores score |
|
LEFT JOIN ex_exam_info info ON info.ID = score.exam_id |
|
AND info.publish_status = 1 |
|
AND info.is_deleted = 0 |
|
LEFT JOIN ex_exam_papers papers ON papers.ID = info.paper_id |
|
AND papers.is_deleted = 0 |
|
WHERE |
|
score.is_deleted = 0 |
|
) |
|
-- 主查询,统计相关信息 |
|
SELECT |
|
1 as "key", |
|
(SELECT "count" FROM exam_Count) AS "examTimes", |
|
(SELECT COUNT(1) FROM scores) AS "participants", |
|
(SELECT AVG(time_spent) FROM scores) AS "averageTime", |
|
ROUND((SELECT COUNT(1) FROM scores WHERE score >= 0.6) * 100.0 / (SELECT COUNT(1) FROM scores), 2) AS "passRate" |
|
]]> |
|
</select> |
|
<select id="getScoreDistributionData" resultType="java.util.Map"> |
|
<![CDATA[ |
|
-- 定义 CTE scores,用于获取考试成绩相关信息 |
|
WITH scores AS ( |
|
SELECT |
|
score.total_score, |
|
papers.total_score, |
|
score.total_score / papers.total_score AS grade, |
|
info.ID |
|
FROM |
|
ex_exam_scores score |
|
LEFT JOIN ex_exam_info info ON info.ID = score.exam_id |
|
AND info.publish_status = 1 |
|
AND info.is_deleted = 0 |
|
LEFT JOIN ex_exam_papers papers ON papers.ID = info.paper_id |
|
AND papers.is_deleted = 0 |
|
WHERE |
|
score.is_deleted = 0 |
|
), |
|
-- 定义 CTE total,用于计算总人数 |
|
total AS ( |
|
SELECT count(1) headcount |
|
FROM |
|
ex_exam_scores score |
|
LEFT JOIN ex_exam_info info ON info.ID = score.exam_id |
|
AND info.publish_status = 1 |
|
AND info.is_deleted = 0 |
|
LEFT JOIN ex_exam_papers papers ON papers.ID = info.paper_id |
|
AND papers.is_deleted = 0 |
|
WHERE |
|
score.is_deleted = 0 |
|
) |
|
-- 主查询部分,计算不同成绩区间的比例并精确到小数点后两位 |
|
SELECT |
|
ROUND(COUNT(1) / (SELECT headcount FROM total) * 100, 2) AS "value" , |
|
'优秀占比: '||ROUND(COUNT(1) / (SELECT headcount FROM total) * 100, 2) || '%' AS "name" |
|
FROM |
|
scores |
|
WHERE |
|
grade >= 0.9 |
|
UNION ALL |
|
SELECT |
|
ROUND(COUNT(1) / (SELECT headcount FROM total) * 100, 2) AS "value" , |
|
'合格占比: '||ROUND(COUNT(1) / (SELECT headcount FROM total) * 100, 2) || '%'AS "name" |
|
FROM |
|
scores |
|
WHERE |
|
grade < 0.9 |
|
AND grade >= 0.6 |
|
UNION ALL |
|
SELECT |
|
ROUND(COUNT(1) / (SELECT headcount FROM total) * 100, 2) AS "value" , |
|
'需努力占比: '||ROUND(COUNT(1) / (SELECT headcount FROM total) * 100, 2) || '%'AS "name" |
|
FROM |
|
scores |
|
WHERE |
|
grade < 0.6; |
|
]]> |
|
</select> |
|
<select id="getPaperDistributionData" resultType="java.util.Map"> |
|
SELECT COUNT |
|
( 1 ) AS "value", |
|
ind.industry_name || ': '|| COUNT( 1 ) || ' 套' AS "name" |
|
FROM |
|
tbl_industry ind |
|
left join ex_exam_papers papers |
|
on papers.industry_id = ind.industry_id |
|
and papers.is_deleted = 0 |
|
AND papers.paper_status = 1 |
|
WHERE |
|
ind.status = 1 |
|
GROUP BY |
|
ind.industry_id , |
|
ind.industry_name |
|
ORDER BY |
|
ind.industry_id |
|
</select> |
|
<select id="getExamAnswerDetails" resultType="java.util.Map"> |
|
|
|
</select> |
|
</mapper> |