Przeglądaj źródła

图生视频任务查询sql优化

cmy 1 miesiąc temu
rodzic
commit
00fe820092

+ 3 - 2
db/ai_volcengine_video_collect.sql

@@ -7,6 +7,7 @@ CREATE TABLE `ai_volcengine_video_collect`  (
                                                 `create_time` datetime NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '创建时间',
                                                 PRIMARY KEY (`id`) USING BTREE,
                                                 INDEX `user_id`(`user_id` ASC) USING BTREE,
-                                                INDEX `task_id`(`task_id` ASC) USING BTREE,
-                                                INDEX `task_detail_id`(`task_detail_id` ASC) USING BTREE
+                                                INDEX `task_detail_id`(`task_detail_id` ASC) USING BTREE,
+                                                INDEX `idx_user_task_detail`(`user_id` ASC, `task_id` ASC, `task_detail_id` ASC) USING BTREE,
+                                                INDEX `idx_user_task`(`user_id` ASC, `task_id` ASC) USING BTREE
 ) ENGINE = InnoDB AUTO_INCREMENT = 1 CHARACTER SET = utf8mb4 COLLATE = utf8mb4_general_ci COMMENT = '火山大模型生成视频收藏表' ROW_FORMAT = Dynamic;

+ 59 - 53
src/main/resources/mapper/ai/volcengine/VolcengineVideoTaskDao.xml

@@ -2,20 +2,24 @@
 <!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd" >
 <mapper namespace="com.backendsys.modules.ai.volcengine.dao.VolcengineVideoTaskDao">
 
-
-    <resultMap id="resultMapTask" type="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTask">
-        <id property="id" column="id" jdbcType="BIGINT" />
-        <result property="user_id" column="user_id" jdbcType="BIGINT" />
-        <result property="model" column="model" jdbcType="VARCHAR" />
-        <result property="img_url" column="img_url"  jdbcType="VARCHAR" />
-        <result property="resolution" column="resolution" jdbcType="VARCHAR" />
-        <result property="duration" column="duration" jdbcType="INTEGER" />
-        <result property="text" column="text" jdbcType="VARCHAR" />
-        <result property="camerafixed" column="camerafixed" jdbcType="INTEGER" />
-        <result property="quantity" column="quantity" jdbcType="INTEGER" />
-        <result property="is_collect" column="is_collect" jdbcType="INTEGER" />
+    <!-- 基础映射 -->
+    <resultMap id="baseTaskMap" type="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTask">
+        <id property="id" column="id"/>
+        <result property="user_id" column="user_id"/>
+        <result property="model" column="model"  />
+        <result property="img_url" column="img_url"  />
+        <result property="resolution" column="resolution" />
+        <result property="duration" column="duration" />
+        <result property="text" column="text" />
+        <result property="camerafixed" column="camerafixed" />
+        <result property="quantity" column="quantity" />
+        <result property="is_collect" column="is_collect" />
         <result property="create_time" column="create_time" />
         <result property="update_time" column="update_time" />
+    </resultMap>
+
+    <!-- 任务映射 -->
+    <resultMap id="resultMapTask" type="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTask" extends="baseTaskMap">
         <collection select="queryDetailById" property="detail_list" javaType="java.util.List"
                     ofType="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTaskDetail" column="{id=id, user_id=user_id}">
             <id property="id" column="id" />
@@ -31,23 +35,12 @@
             <result property="error_msg" column="error_msg" />
             <result property="create_time" column="create_time" />
             <result property="update_time" column="update_time" />
-            <result property="is_collect" column="is_collect" jdbcType="INTEGER" />
+            <result property="is_collect" column="is_collect" />
         </collection>
     </resultMap>
 
-    <resultMap id="resultMapTaskCollect" type="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTask">
-        <id property="id" column="id" jdbcType="BIGINT" />
-        <result property="user_id" column="user_id" jdbcType="BIGINT" />
-        <result property="model" column="model" jdbcType="VARCHAR" />
-        <result property="img_url" column="img_url"  jdbcType="VARCHAR" />
-        <result property="resolution" column="resolution" jdbcType="VARCHAR" />
-        <result property="duration" column="duration" jdbcType="INTEGER" />
-        <result property="text" column="text" jdbcType="VARCHAR" />
-        <result property="camerafixed" column="camerafixed" jdbcType="INTEGER" />
-        <result property="quantity" column="quantity" jdbcType="INTEGER" />
-        <result property="is_collect" column="is_collect" jdbcType="INTEGER" />
-        <result property="create_time" column="create_time" />
-        <result property="update_time" column="update_time" />
+    <!-- 收藏任务映射 -->
+    <resultMap id="resultMapTaskCollect" type="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTask" extends="baseTaskMap">
         <collection select="queryDetailCollectById" property="detail_list" javaType="java.util.List"
                     ofType="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTaskDetail" column="{id=id, user_id=user_id}">
             <id property="id" column="id" />
@@ -63,70 +56,83 @@
             <result property="error_msg" column="error_msg" />
             <result property="create_time" column="create_time" />
             <result property="update_time" column="update_time" />
-            <result property="is_collect" column="is_collect" jdbcType="INTEGER" />
+            <result property="is_collect" column="is_collect" />
         </collection>
     </resultMap>
 
+    <!-- 根据用户id 获取任务列表,标记用户是否收藏 -->
     <select id="selectTaskList" resultMap="resultMapTask">
         SELECT avvt.*,
-               (case when (select count(1)
-                           from ai_volcengine_video_collect
-                           where task_id=avvt.id and user_id=#{dto.user_id})>0
-                   then 1 else 0 end) as is_collect
+        IF(avc.task_id IS NOT NULL, 1, 0) as is_collect
         from ai_volcengine_video_task avvt
+        LEFT JOIN (
+        SELECT DISTINCT task_id
+        FROM ai_volcengine_video_collect
+        WHERE user_id = #{dto.user_id}
+        ) avc ON avc.task_id = avvt.id
         <where>
             <if test="dto.model != null and dto.model != ''">
                 and avvt.model = #{dto.model}
             </if>
-            <if test="dto.create_begin_date != null and dto.create_begin_date != '' and dto.create_end_date !=null and dto.create_end_date != ''">
-                and date_format(avvt.create_time,'%Y-%m-%d') BETWEEN #{dto.create_begin_date} and #{dto.create_end_date}
+            <if test="dto.create_begin_date != null and dto.create_begin_date != ''">
+                AND avvt.create_time >= STR_TO_DATE(#{dto.create_begin_date}, '%Y-%m-%d')
+            </if>
+            <if test="dto.create_end_date != null and dto.create_end_date != ''">
+                AND avvt.create_time &lt; DATE_ADD(STR_TO_DATE(#{dto.create_end_date}, '%Y-%m-%d'), INTERVAL 1 DAY)
             </if>
         </where>
         order by create_time desc
     </select>
 
+    <!-- 根据任务id和用户id 查询任务明细视频,标记用户是否收藏 -->
     <select id="queryDetailById" resultType="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTaskDetail">
         SELECT avvtd.*,
-               (case when (select count(1)
-                           from ai_volcengine_video_collect
-                           where task_id=avvtd.task_id and task_detail_id=avvtd.id and user_id=#{user_id})>0
-                   then 1 else 0 end) as is_collect
+               IF(avc.task_id IS NOT NULL, 1, 0) as is_collect
         FROM ai_volcengine_video_task_detail avvtd
+        LEFT JOIN ai_volcengine_video_collect avc
+            ON avc.task_id = avvtd.task_id
+            AND avc.task_detail_id = avvtd.id
+            AND avc.user_id = #{user_id}
         WHERE avvtd.task_id = #{id}
         order by update_time desc
     </select>
 
+    <!-- 根据用户id 获取用户已收藏的任务列表 -->
     <select id="selectTaskCollectList"
             resultMap="resultMapTaskCollect">
-        select * from (SELECT avvt.*,
-               (case when (select count(1)
-                           from ai_volcengine_video_collect
-                           where task_id=avvt.id and user_id=#{dto.user_id})>0
-                         then 1 else 0 end) as is_collect
+        SELECT avvt.*,
+               1 as is_collect
         from ai_volcengine_video_task avvt
+        INNER JOIN (
+        SELECT DISTINCT task_id
+        FROM ai_volcengine_video_collect
+        WHERE user_id = #{dto.user_id}
+        ) avc ON avc.task_id = avvt.id
         <where>
             <if test="dto.model != null and dto.model != ''">
                 and avvt.model = #{dto.model}
             </if>
-            <if test="dto.create_begin_date != null and dto.create_begin_date != '' and dto.create_end_date !=null and dto.create_end_date != ''">
-                and date_format(avvt.create_time,'%Y-%m-%d') BETWEEN #{dto.create_begin_date} and #{dto.create_end_date}
+            <if test="dto.create_begin_date != null and dto.create_begin_date != ''">
+                AND avvt.create_time >= STR_TO_DATE(#{dto.create_begin_date}, '%Y-%m-%d')
+            </if>
+            <if test="dto.create_end_date != null and dto.create_end_date != ''">
+                AND avvt.create_time &lt; DATE_ADD(STR_TO_DATE(#{dto.create_end_date}, '%Y-%m-%d'), INTERVAL 1 DAY)
             </if>
         </where>
         order by create_time desc
-        ) t
-        where t.is_collect=1
     </select>
 
+    <!-- 根据任务id和用户id 查询收藏的任务明细视频 -->
     <select id="queryDetailCollectById" resultType="com.backendsys.modules.ai.volcengine.entity.VolcengineVideoTaskDetail">
-        select * from (SELECT avvtd.*,
-               (case when (select count(1)
-                           from ai_volcengine_video_collect
-                           where task_id=avvtd.task_id and task_detail_id=avvtd.id and user_id=#{user_id})>0
-                         then 1 else 0 end) as is_collect
+        SELECT avvtd.*,
+               1 as is_collect
         FROM ai_volcengine_video_task_detail avvtd
+        INNER JOIN ai_volcengine_video_collect avc
+            ON avc.task_id = avvtd.task_id
+            AND avc.task_detail_id = avvtd.id
+            AND avc.user_id = #{user_id}
         WHERE avvtd.task_id = #{id}
         order by update_time desc
-        ) t
-        where t.is_collect=1
     </select>
+
 </mapper>