From c6c6912c7ef5dae0356b465c1a0a6ecb94960326 Mon Sep 17 00:00:00 2001 From: shiziyuan9527 <yuhao.li@fit2cloud.com> Date: Mon, 11 Jul 2022 11:30:43 +0800 Subject: [PATCH] =?UTF-8?q?refactor(=E9=A1=B9=E7=9B=AE=E8=AE=BE=E7=BD=AE):?= =?UTF-8?q?=20=E5=AE=9A=E6=97=B6=E6=B8=85=E7=90=86=E6=8E=A5=E5=8F=A3?= =?UTF-8?q?=E6=8A=A5=E5=91=8A=E4=BC=98=E5=8C=96?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .../api/service/ApiScenarioReportService.java | 14 +- .../ext/ExtApiDefinitionExecResultMapper.java | 2 + .../ext/ExtApiDefinitionExecResultMapper.xml | 274 +++++++++++++----- .../ext/ExtApiScenarioReportMapper.java | 2 +- .../mapper/ext/ExtApiScenarioReportMapper.xml | 3 + 5 files changed, 212 insertions(+), 83 deletions(-) diff --git a/backend/src/main/java/io/metersphere/api/service/ApiScenarioReportService.java b/backend/src/main/java/io/metersphere/api/service/ApiScenarioReportService.java index 073fb4fe01..87b8c5522e 100644 --- a/backend/src/main/java/io/metersphere/api/service/ApiScenarioReportService.java +++ b/backend/src/main/java/io/metersphere/api/service/ApiScenarioReportService.java @@ -735,7 +735,7 @@ public class ApiScenarioReportService { reportRequest.setIds(myList); //为预防数量太多,调用删除方法时引起SQL过长的Bug,此处采取分批执行的方式。 //每次处理的数据数量 - int handleCount = 7000; + int handleCount = 5000; //每次处理的集合 while (ids.size() > handleCount) { List<String> handleIdList = new ArrayList<>(handleCount); @@ -917,16 +917,8 @@ public class ApiScenarioReportService { } public void cleanUpReport(long time, String projectId) { - ApiScenarioReportExample example = new ApiScenarioReportExample(); - example.createCriteria().andCreateTimeLessThan(time).andProjectIdEqualTo(projectId); - List<ApiScenarioReport> apiScenarioReports = apiScenarioReportMapper.selectByExample(example); - List<String> ids = apiScenarioReports.stream().map(ApiScenarioReport::getId).collect(Collectors.toList()); - - ApiDefinitionExecResultExample definitionExecResultExample = new ApiDefinitionExecResultExample(); - definitionExecResultExample.createCriteria().andCreateTimeLessThan(time).andProjectIdEqualTo(projectId); - List<ApiDefinitionExecResult> apiDefinitionExecResults = definitionExecResultMapper.selectByExample(definitionExecResultExample); - List<String> definitionExecIds = apiDefinitionExecResults.stream().map(ApiDefinitionExecResult::getId).collect(Collectors.toList()); - + List<String> ids = extApiScenarioReportMapper.selectByProjectIdAndLessThanTime(projectId, time); + List<String> definitionExecIds = extApiDefinitionExecResultMapper.selectByProjectIdAndLessThanTime(projectId, time); ids.addAll(definitionExecIds); if (CollectionUtils.isNotEmpty(ids)) { APIReportBatchRequest request = new APIReportBatchRequest(); diff --git a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.java b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.java index 0afab6d28c..5e74fd03a8 100644 --- a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.java +++ b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.java @@ -47,4 +47,6 @@ public interface ExtApiDefinitionExecResultMapper { List<ApiDefinitionExecResult> findByProjectIds(@Param("request") TaskCenterRequest request); List<String> selectDistinctStatusByReportId(String reportId); + + List<String> selectByProjectIdAndLessThanTime(@Param("projectId") String projectId, @Param("time") long time); } diff --git a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.xml b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.xml index 5ed7c8d2bf..64c039f756 100644 --- a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.xml +++ b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiDefinitionExecResultMapper.xml @@ -3,97 +3,223 @@ <mapper namespace="io.metersphere.base.mapper.ext.ExtApiDefinitionExecResultMapper"> <delete id="deleteByResourceId" parameterType="java.lang.String"> delete - from api_definition_exec_result where resource_id = #{id,jdbcType=VARCHAR} + from api_definition_exec_result + where resource_id = #{id,jdbcType=VARCHAR} </delete> - <select id="selectMaxResultByResourceId" parameterType="java.lang.String" resultType="io.metersphere.base.domain.ApiDefinitionExecResult"> - select * from api_definition_exec_result - where resource_id = #{resourceId,jdbcType=VARCHAR} ORDER BY create_time DESC LIMIT 1 + <select id="selectMaxResultByResourceId" parameterType="java.lang.String" + resultType="io.metersphere.base.domain.ApiDefinitionExecResultWithBLOBs"> + select * + from api_definition_exec_result + where resource_id = #{resourceId,jdbcType=VARCHAR} + ORDER BY create_time DESC LIMIT 1 </select> <select id="selectMaxResultByResourceIdAndType" - resultType="io.metersphere.base.domain.ApiDefinitionExecResult"> - select * from api_definition_exec_result - where resource_id = #{resourceId,jdbcType=VARCHAR} and `type` = #{type, jdbcType=VARCHAR} + resultType="io.metersphere.base.domain.ApiDefinitionExecResultWithBLOBs"> + select * + from api_definition_exec_result + where resource_id = #{resourceId,jdbcType=VARCHAR} + and `type` = #{type, jdbcType=VARCHAR} ORDER BY start_time DESC LIMIT 5, 1 </select> <select id="countByProjectIDAndCreateInThisWeek" resultType="java.lang.Long"> - SELECT count(id) AS countNumber FROM api_definition_exec_result - WHERE resource_id IN ( - SELECT testCase.id FROM api_test_case testCase - WHERE testCase.project_id = #{projectId}) - and start_time BETWEEN #{firstDayTimestamp} AND #{lastDayTimestamp} + SELECT count(id) AS countNumber + FROM api_definition_exec_result + WHERE resource_id IN (SELECT testCase.id + FROM api_test_case testCase + WHERE testCase.project_id = #{projectId}) + and start_time BETWEEN #{firstDayTimestamp} AND #{lastDayTimestamp} </select> <select id="countByTestCaseIDInProject" resultType="java.lang.Long"> - SELECT count(id) AS countNumber FROM api_definition_exec_result - WHERE resource_id IN ( - SELECT testCase.id FROM api_test_case testCase - WHERE testCase.project_id = #{projectId}) + SELECT count(id) AS countNumber + FROM api_definition_exec_result + WHERE resource_id IN (SELECT testCase.id + FROM api_test_case testCase + WHERE testCase.project_id = #{projectId}) </select> <select id="selectDistinctStatusByReportId" resultType="java.lang.String"> - SELECT DISTINCT status FROM api_definition_exec_result WHERE integrated_report_id = #{0} + SELECT DISTINCT status + FROM api_definition_exec_result + WHERE integrated_report_id = #{0} </select> - <select id="findFaliureCaseInfoByProjectIDAndExecuteTimeAndLimitNumber" resultType="io.metersphere.api.dto.datacount.ExecutedCaseInfoResult"> - SELECT * FROM ( - -- api_test_case 只查找测试计划执行的结果 - SELECT testCase.testCaseID AS testCaseID,testCase.id AS id,testCase.testCaseName AS caseName,testCase.testPlanName AS testPlan ,caseErrorCountData.dataCountNumber AS failureTimes,'apiCase' AS caseType - FROM ( - SELECT testPlanCase.id AS testPlanCaseID, testPlanCase.api_case_id as testCaseID, apiCase.id AS id,apiCase.`name` AS testCaseName,testPlan.`name` AS testPlanName, testPlanCase.update_time as updateTime - FROM api_test_case apiCase - inner join api_definition on api_definition.id = apiCase.api_definition_id - INNER JOIN test_plan_api_case testPlanCase ON testPlanCase.api_case_id = apiCase.id - INNER JOIN test_plan testPlan ON testPlan.id = testPlanCase.test_plan_id - and api_definition.status != 'Trash' - ORDER BY apiCase.create_time DESC - )testCase + <select id="findFaliureCaseInTestPlanByProjectIDAndExecuteTimeAndLimitNumber" + resultType="io.metersphere.api.dto.datacount.ExecutedCaseInfoResult"> + SELECT * + FROM ( + SELECT testCase.testPlanCaseID AS testPlanCaseID, + testCase.id AS id, + testCase.testCaseName AS caseName, + testCase.testPlanName AS testPlan, + testCase.testPlanId AS testPlanId, + caseErrorCountData.dataCountNumber AS failureTimes, + 'apiCase' AS caseType + FROM (SELECT testPlanCase.id AS testPlanCaseID, + apiCase.id AS id, + apiCase.`name` AS testCaseName, + testPlan.id AS testPlanId, + testPlan.`name` AS testPlanName + FROM api_test_case apiCase + INNER JOIN test_plan_api_case testPlanCase ON testPlanCase.api_case_id = apiCase.id + INNER JOIN test_plan testPlan ON testPlan.id = testPlanCase.test_plan_id + WHERE ( + apiCase.`status` IS NULL + OR apiCase.`status` != 'Trash' + AND apiCase.project_id = #{projectId})) testCase + INNER JOIN (SELECT executionInfo.source_id AS sourceId, + COUNT(executionInfo.id) AS dataCountNumber + FROM api_case_execution_info executionInfo + INNER JOIN test_plan_api_case testPlanCase + ON executionInfo.source_id = testPlanCase.id + WHERE executionInfo.`result` = 'error' + AND executionInfo.create_time > #{startTimestamp} + GROUP BY source_id) caseErrorCountData + ON caseErrorCountData.sourceId = testCase.testPlanCaseID + UNION + + SELECT scene.id AS testCaseID, + scene.id AS id, + scene.`name` AS caseName, + apiScene.testPlanName AS testPlan, + apiScene.testPlanId AS testPlanId, + count(executionInfo.id) AS failureTimes, + 'scenario' AS caseType + FROM scenario_execution_info executionInfo + INNER JOIN (SELECT testPlanScenario.id, + testPlanScenario.api_scenario_id, + testPlan.id AS testPlanId, + testPlan.`name` AS testPlanName + FROM test_plan_api_scenario testPlanScenario + INNER JOIN test_plan testPlan ON testPlan.id = testPlanScenario.test_plan_id) apiScene + ON apiScene.id = executionInfo.source_id + INNER JOIN api_scenario scene ON scene.id = apiScene.api_scenario_id + + WHERE scene.project_id = #{projectId} + AND scene.`status` != 'Trash' + AND ( executionInfo.result = 'Error' OR executionInfo.result = 'Fail' ) + AND executionInfo.create_time >= #{startTimestamp} + GROUP BY + scene.id + <if test="selectFunctionCase == true"> + UNION + SELECT + testCase.id AS testCaseID, + testCase.id AS id, + testCase.`name` AS caseName, + testCasePlan.testPlanName AS testPlan, + testCasePlan.testPlanId AS testPlanId, + count( executionInfo.id ) AS failureTimes, + 'testCase' AS caseType + FROM + function_case_execution_info executionInfo INNER JOIN ( - SELECT resource_id AS testPlanCaseID,COUNT(id) AS dataCountNumber,start_time AS executeTime FROM api_definition_exec_result - WHERE resource_id IN ( - SELECT t2.id FROM api_test_case t1 - INNER JOIN test_plan_api_case t2 ON t1.id = t2.api_case_id - WHERE t1.project_id = #{projectId} - ) and `status` = 'error' GROUP BY resource_id - ) caseErrorCountData ON caseErrorCountData.testPlanCaseID =testCase.testPlanCaseID - WHERE testCase.updateTime >= #{startTimestamp} - UNION - SELECT scene.id AS testCaseID,scene.id AS id,scene.`name` AS caseName,apiScene.testPlanName AS testPlan,count(report.id) AS failureTimes,'scenario' AS caseType - FROM api_scenario_report report - INNER JOIN api_scenario scene ON report.scenario_id = scene.id - INNER JOIN( - SELECT apiScene.api_scenario_id, group_concat(testPlan.`name`) AS testPlanName - FROM test_plan_api_scenario apiScene - INNER JOIN test_plan testPlan ON testPlan.id = apiScene.test_plan_id - GROUP BY apiScene.api_scenario_id - )apiScene ON apiScene.api_scenario_id = scene.id - WHERE report.project_id = #{projectId} - AND scene.`status` != 'Trash' + SELECT + testPlanTestCase.id, + testPlanTestCase.case_id, + testPlan.id AS testPlanId, + testPlan.`name` AS testPlanName + FROM + test_plan_test_case testPlanTestCase + INNER JOIN test_plan testPlan ON testPlan.id = testPlanTestCase.plan_id + ) testCasePlan ON testCasePlan.id = executionInfo.source_id + INNER JOIN test_case testCase ON testCase.id = testCasePlan.case_id + WHERE + testCase.project_id = #{projectId} + AND testCase.`status` != 'Trash' + AND ( executionInfo.result = 'Failure' ) + AND executionInfo.create_time >= #{startTimestamp} + GROUP BY + testCase.id + </if> + ) showTable + ORDER BY showTable.failureTimes DESC + </select> + <select id="findFaliureCaseInfoByProjectIDAndExecuteTimeAndLimitNumber" + resultType="io.metersphere.api.dto.datacount.ExecutedCaseInfoResult"> + SELECT * + FROM ( + -- api_test_case 只查找测试计划执行的结果 + SELECT testCase.testCaseID AS testCaseID, + testCase.id AS id, + testCase.testCaseName AS caseName, + testCase.testPlanName AS testPlan, + caseErrorCountData.dataCountNumber AS failureTimes, + 'apiCase' AS caseType + FROM (SELECT testPlanCase.id AS testPlanCaseID, + testPlanCase.api_case_id as testCaseID, + apiCase.id AS id, + apiCase.`name` AS testCaseName, + testPlan.`name` AS testPlanName, + testPlanCase.update_time as updateTime + FROM api_test_case apiCase + inner join api_definition on api_definition.id = apiCase.api_definition_id + INNER JOIN test_plan_api_case testPlanCase ON testPlanCase.api_case_id = apiCase.id + INNER JOIN test_plan testPlan ON testPlan.id = testPlanCase.test_plan_id + and api_definition.status != 'Trash' + ORDER BY apiCase.create_time DESC) testCase + INNER JOIN (SELECT resource_id AS testPlanCaseID, + COUNT(id) AS dataCountNumber, + start_time AS executeTime + FROM api_definition_exec_result + WHERE resource_id IN (SELECT t2.id + FROM api_test_case t1 + INNER JOIN test_plan_api_case t2 ON t1.id = t2.api_case_id + WHERE t1.project_id = #{projectId}) + and `status` = 'error' + GROUP BY resource_id) caseErrorCountData + ON caseErrorCountData.testPlanCaseID = testCase.testPlanCaseID + WHERE testCase.updateTime >= #{startTimestamp} + UNION + SELECT ltr.test_id as testCaseID, + ltr.id AS id, + ltr.name as caseName, + tplt.testPlanName AS testPlan, + count(ltr.id) as failureTimes, + 'load' as caseType + FROM load_test_report ltr + join load_test on load_test.id = ltr.test_id + JOIN (select tplc.load_case_id, group_concat(tp.`name`) AS testPlanName, tp.project_id + from test_plan_load_case tplc + join test_plan tp on tp.id = tplc.test_plan_id + GROUP BY tplc.load_case_id) tplt on tplt.load_case_id = ltr.test_id + WHERE load_test.project_id = #{projectId} + AND ltr.STATUS = 'Error' + and ltr.trigger_mode = 'TEST_PLAN_SCHEDULE' + AND ltr.create_time >= #{startTimestamp} + GROUP BY load_test.id + UNION + SELECT scene.id AS testCaseID, + scene.id AS id, + scene.`name` AS caseName, + apiScene.testPlanName AS testPlan, + count(report.id) AS failureTimes, + 'scenario' AS caseType + FROM api_scenario_report report + INNER JOIN api_scenario scene ON report.scenario_id = scene.id + INNER JOIN(SELECT apiScene.api_scenario_id, group_concat(testPlan.`name`) AS testPlanName + FROM test_plan_api_scenario apiScene + INNER JOIN test_plan testPlan ON testPlan.id = apiScene.test_plan_id + GROUP BY apiScene.api_scenario_id) apiScene ON apiScene.api_scenario_id = scene.id + WHERE report.project_id = #{projectId} + AND scene.`status` != 'Trash' AND ( report.STATUS = 'Error' OR report.STATUS = 'Fail' ) AND report.create_time >= #{startTimestamp} - GROUP BY scene.id - UNION - SELECT ltr.test_id as testCaseID,ltr.id AS id, ltr.name as caseName,tplt.testPlanName AS testPlan, count(ltr.id) as failureTimes, 'load' as caseType FROM load_test_report ltr - join load_test on load_test.id = ltr.test_id - JOIN ( - select tplc.load_case_id, group_concat(tp.`name`) AS testPlanName, tp.project_id - from test_plan_load_case tplc - join test_plan tp on tp.id = tplc.test_plan_id - GROUP BY tplc.load_case_id - ) tplt on tplt.load_case_id = ltr.test_id - WHERE load_test.project_id = #{projectId} - AND ltr.STATUS = 'Error' and ltr.trigger_mode = 'TEST_PLAN_SCHEDULE' AND ltr.create_time >= #{startTimestamp} - GROUP BY load_test.id - ) showTable + GROUP BY scene.id) showTable ORDER BY showTable.failureTimes DESC </select> <select id="selectExecResult" resultType="java.lang.String"> - select ader.status from api_definition_exec_result ader where ader.resource_id=#{resourceId} - </select> + select ader.status + from api_definition_exec_result ader + where ader.resource_id = #{resourceId} + </select> <select id="selectPlanApiMaxResultByTestIdAndType" - resultType="io.metersphere.base.domain.ApiDefinitionExecResult"> - select * from api_definition_exec_result - where resource_id = #{resourceId,jdbcType=VARCHAR} and `type` = #{type, jdbcType=VARCHAR} + resultType="io.metersphere.base.domain.ApiDefinitionExecResultWithBLOBs"> + select * + from api_definition_exec_result + where resource_id = #{resourceId,jdbcType=VARCHAR} + and `type` = #{type, jdbcType=VARCHAR} ORDER BY start_time DESC LIMIT 1 </select> @@ -284,10 +410,16 @@ </foreach> </update> - <select id="findByProjectIds" resultType="io.metersphere.base.domain.ApiDefinitionExecResult" parameterType="java.lang.String"> - select actuator ,id from api_definition_exec_result where status in ("running","starting","waiting") and project_id in + <select id="findByProjectIds" resultType="io.metersphere.base.domain.ApiDefinitionExecResult" + parameterType="java.lang.String"> + select actuator ,id from api_definition_exec_result where status in ("running","starting","waiting") and + project_id in <foreach collection="request.projects" item="id" separator="," open="(" close=")"> #{id} </foreach> </select> + <select id="selectByProjectIdAndLessThanTime" resultType="java.lang.String"> + select id from api_definition_exec_result where project_id = #{projectId} and create_time < #{time} + </select> + </mapper> diff --git a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.java b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.java index ed28914fae..6999e7f194 100644 --- a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.java +++ b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.java @@ -47,5 +47,5 @@ public interface ExtApiScenarioReportMapper { List<ApiScenarioReport> findByProjectIds(@Param("request") TaskCenterRequest request); - + List<String> selectByProjectIdAndLessThanTime(@Param("projectId") String projectId, @Param("time") long time); } diff --git a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.xml b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.xml index 7ddf62935b..1a6789880b 100644 --- a/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.xml +++ b/backend/src/main/java/io/metersphere/base/mapper/ext/ExtApiScenarioReportMapper.xml @@ -461,5 +461,8 @@ #{id} </foreach> </select> + <select id="selectByProjectIdAndLessThanTime" resultType="java.lang.String"> + select id from api_scenario_report where create_time < #{time} and project_id = #{projectId} + </select> </mapper>