You've already forked FrameTour-BE
- 将 filterExistingRelations 查询中的 if 判断替换为 choose-when 结构 - 在 otherwise 分支中添加空结果集查询,避免空列表时 SQL 异常- 统一 filterValidSourceRelations 查询结构,增强代码一致性 -修正 foreach 标签中 UNION ALL 前后的空格问题,确保 SQL 语法正确- 提升 XML 映射文件的可读性和健壮性
354 lines
15 KiB
XML
354 lines
15 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="com.ycwl.basic.mapper.SourceMapper">
|
|
<insert id="add">
|
|
insert into source(id, scenic_id, device_id, url, video_url, `type`, face_sample_id, pos_json, create_time)
|
|
values (#{id}, #{scenicId}, #{deviceId}, #{url}, #{videoUrl}, #{type}, #{faceSampleId}, #{posJson}, #{createTime})
|
|
</insert>
|
|
<insert id="addRelation">
|
|
replace member_source(scenic_id, face_id, member_id, source_id, is_buy, type, order_id<if test="isFree">, is_free</if>)
|
|
values (#{scenicId}, #{faceId}, #{memberId}, #{sourceId}, #{isBuy}, #{type}, #{orderId}<if test="isFree">, #{isFree}</if>)
|
|
</insert>
|
|
<insert id="addRelations">
|
|
insert IGNORE member_source(scenic_id, face_id, member_id, source_id, is_buy, type, order_id, is_free)
|
|
values
|
|
<foreach collection="list" item="item" separator=",">
|
|
(#{item.scenicId}, #{item.faceId}, #{item.memberId}, #{item.sourceId}, #{item.isBuy}, #{item.type}, #{item.orderId}, #{item.isFree})
|
|
</foreach>
|
|
</insert>
|
|
<select id="filterExistingRelations" resultType="com.ycwl.basic.model.pc.source.entity.MemberSourceEntity">
|
|
<choose>
|
|
<when test="list != null and list.size() > 0">
|
|
SELECT
|
|
r.memberId as memberId,
|
|
r.sourceId as sourceId,
|
|
r.type as type,
|
|
r.faceId as faceId,
|
|
r.scenicId as scenicId,
|
|
r.isBuy as isBuy,
|
|
r.orderId as orderId,
|
|
r.isFree as isFree,
|
|
r.id as id
|
|
FROM (
|
|
<foreach collection="list" item="item" separator=" UNION ALL ">
|
|
SELECT
|
|
#{item.memberId} as memberId,
|
|
#{item.sourceId} as sourceId,
|
|
#{item.type} as type,
|
|
#{item.faceId} as faceId,
|
|
#{item.scenicId} as scenicId,
|
|
#{item.isBuy} as isBuy,
|
|
#{item.orderId} as orderId,
|
|
#{item.isFree} as isFree,
|
|
#{item.id} as id
|
|
</foreach>
|
|
) r
|
|
WHERE NOT EXISTS (
|
|
SELECT 1 FROM member_source ms
|
|
WHERE ms.member_id = r.memberId
|
|
AND ms.source_id = r.sourceId
|
|
AND ms.type = r.type
|
|
AND ms.face_id = r.faceId
|
|
)
|
|
</when>
|
|
<otherwise>
|
|
SELECT
|
|
NULL as memberId,
|
|
NULL as sourceId,
|
|
NULL as type,
|
|
NULL as faceId,
|
|
NULL as scenicId,
|
|
NULL as isBuy,
|
|
NULL as orderId,
|
|
NULL as isFree,
|
|
NULL as id
|
|
WHERE 1 = 0
|
|
</otherwise>
|
|
</choose>
|
|
</select>
|
|
<select id="sourceExists" resultType="boolean">
|
|
SELECT COUNT(1) > 0 FROM source WHERE id = #{sourceId}
|
|
</select>
|
|
<select id="filterValidSourceRelations" resultType="com.ycwl.basic.model.pc.source.entity.MemberSourceEntity">
|
|
<choose>
|
|
<when test="list != null and list.size() > 0">
|
|
SELECT
|
|
r.memberId as memberId,
|
|
r.sourceId as sourceId,
|
|
r.type as type,
|
|
r.faceId as faceId,
|
|
r.scenicId as scenicId,
|
|
r.isBuy as isBuy,
|
|
r.orderId as orderId,
|
|
r.isFree as isFree,
|
|
r.id as id
|
|
FROM (
|
|
<foreach collection="list" item="item" separator=" UNION ALL ">
|
|
SELECT
|
|
#{item.memberId} as memberId,
|
|
#{item.sourceId} as sourceId,
|
|
#{item.type} as type,
|
|
#{item.faceId} as faceId,
|
|
#{item.scenicId} as scenicId,
|
|
#{item.isBuy} as isBuy,
|
|
#{item.orderId} as orderId,
|
|
#{item.isFree} as isFree,
|
|
#{item.id} as id
|
|
</foreach>
|
|
) r
|
|
WHERE EXISTS (
|
|
SELECT 1 FROM source s WHERE s.id = r.sourceId
|
|
)
|
|
</when>
|
|
<otherwise>
|
|
SELECT
|
|
NULL as memberId,
|
|
NULL as sourceId,
|
|
NULL as type,
|
|
NULL as faceId,
|
|
NULL as scenicId,
|
|
NULL as isBuy,
|
|
NULL as orderId,
|
|
NULL as isFree,
|
|
NULL as id
|
|
WHERE 1 = 0
|
|
</otherwise>
|
|
</choose>
|
|
</select>
|
|
<insert id="addSourceWatermark">
|
|
insert source_watermark(source_id, face_id, watermark_type, watermark_url)
|
|
values (#{sourceId}, #{faceId}, #{type}, #{url})
|
|
</insert>
|
|
<update id="update">
|
|
update source
|
|
<set>
|
|
<if test="scenicId!= null">scenic_id = #{scenicId}, </if>
|
|
<if test="deviceId!= null">device_id = #{deviceId}, </if>
|
|
<if test="url!= null">url = #{url}, </if>
|
|
<if test="videoUrl!= null">video_url = #{videoUrl}, </if>
|
|
<if test="isBuy!=null">is_buy = #{isBuy}, </if>
|
|
<if test="type!=null">`type` = #{type}, </if>
|
|
<if test="faceSampleId!= null">face_sample_id = #{faceSampleId}, </if>
|
|
<if test="posJson!= null">pos_json = #{posJson}, </if>
|
|
</set>
|
|
where id = #{id}
|
|
</update>
|
|
<update id="updateRelation">
|
|
update member_source
|
|
<set>
|
|
<if test="isBuy!=null">is_buy = #{isBuy}, </if>
|
|
<if test="orderId!=null">order_id = #{orderId}, </if>
|
|
</set>
|
|
where member_id = #{memberId} and face_id = #{faceId} and `type` = #{type}
|
|
</update>
|
|
<update id="freeRelations">
|
|
update member_source
|
|
set is_free = 1
|
|
where type = #{type} and id in
|
|
<foreach item="item" collection="ids" open="(" separator="," close=")">
|
|
#{item}
|
|
</foreach>
|
|
</update>
|
|
<delete id="deleteById">
|
|
delete from source where id = #{id}
|
|
</delete>
|
|
<delete id="deleteNotRelateSource">
|
|
delete from `source`
|
|
where id not in (select source_id from member_source)
|
|
and type = #{type}
|
|
and create_time <= #{endDate}
|
|
</delete>
|
|
<delete id="deleteNotBuyRelations">
|
|
delete from member_source
|
|
where scenic_id = #{scenicId} and is_buy = 0 and create_time <= #{endDate}
|
|
</delete>
|
|
<delete id="deleteNotBuyFaceRelation">
|
|
delete from member_source
|
|
where member_id = #{userId} and face_id = #{faceId} and is_buy = 0
|
|
</delete>
|
|
<delete id="deleteUselessSource">
|
|
delete from source where id not in (select source_id from member_source) and face_sample_id not in (select id from face_sample)
|
|
</delete>
|
|
|
|
<select id="list" resultType="com.ycwl.basic.model.pc.source.resp.SourceRespVO">
|
|
select so.id, so.scenic_id, device_id, url, so.create_time, so.update_time,so.video_url, so.`type`, so.face_sample_id
|
|
from source so
|
|
<where>
|
|
<if test="scenicId!= null">and so.scenic_id = #{scenicId} </if>
|
|
<if test="deviceId!= null">and device_id = #{deviceId} </if>
|
|
<if test="url!= null">and url = #{url} </if>
|
|
<if test="isBuy!=null">
|
|
and is_buy = #{isBuy}
|
|
</if>
|
|
<if test="type!=null">and so.type = #{type} </if>
|
|
<if test="startTime!= null">and so.create_time >= #{startTime} </if>
|
|
<if test="endTime!= null">and so.create_time <= #{endTime} </if>
|
|
</where>
|
|
order by so.create_time desc
|
|
</select>
|
|
<select id="userGetById" resultType="com.ycwl.basic.model.pc.source.resp.SourceRespVO">
|
|
select so.id, ms.scenic_id, device_id, ms.member_id, url, ms.is_free, so.create_time, so.update_time
|
|
from member_source ms
|
|
left join source so on ms.source_id = so.id
|
|
|
|
where so.id = #{id} and ms.member_id = #{userId} and so.id is not null
|
|
</select>
|
|
<select id="getById" resultType="com.ycwl.basic.model.pc.source.resp.SourceRespVO">
|
|
select so.id, scenic_id, device_id, url, video_url, so.create_time, so.update_time
|
|
from source so
|
|
|
|
where so.id = #{id}
|
|
</select>
|
|
<select id="listGroupByType" resultType="com.ycwl.basic.model.pc.source.resp.SourceRespVO">
|
|
select ms.type, ms.is_buy
|
|
from member_source ms
|
|
<where>
|
|
<if test="scenicId!= null">and ms.scenic_id = #{scenicId} </if>
|
|
<if test="memberId!= null">and ms.member_id = #{memberId} </if>
|
|
<if test="isBuy!=null">and ms.is_buy = #{isBuy}</if>
|
|
</where>
|
|
group by ms.type
|
|
</select>
|
|
<select id="countByMemberId" resultType="java.lang.Integer">
|
|
select count(1) from member_source where member_id = #{userId}
|
|
</select>
|
|
<select id="listBySampleIds" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select *
|
|
from source
|
|
where face_sample_id in
|
|
<foreach collection="list" item="item" open="(" separator="," close=")">
|
|
#{item}
|
|
</foreach>
|
|
order by create_time desc
|
|
</select>
|
|
<select id="listVideoBySampleIds" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select *
|
|
from source
|
|
where face_sample_id in
|
|
<foreach collection="list" item="item" open="(" separator="," close=")">
|
|
#{item}
|
|
</foreach>
|
|
and type = 1
|
|
</select>
|
|
<select id="findBySampleId" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select *
|
|
from source
|
|
where type = 2 and face_sample_id = #{faceSampleId}
|
|
limit 1
|
|
</select>
|
|
<select id="listUser" resultType="com.ycwl.basic.model.pc.source.resp.SourceRespVO">
|
|
select so.id, ms.scenic_id, device_id, url, ms.is_free, so.create_time, so.update_time, ms.is_buy, video_url
|
|
from member_source ms
|
|
left join source so on ms.source_id = so.id
|
|
|
|
where
|
|
ms.member_id = #{memberId} and so.id is not null
|
|
<if test="scenicId!= null">and ms.scenic_id = #{scenicId} </if>
|
|
<if test="isBuy!=null">and ms.is_buy = #{isBuy} </if>
|
|
<if test="type!=null">and ms.type = #{type} </if>
|
|
<if test="faceId!=null">and ms.face_id = #{faceId} </if>
|
|
order by ms.is_free desc, so.create_time asc
|
|
</select>
|
|
|
|
<select id="listUserOne" resultType="com.ycwl.basic.model.pc.source.resp.SourceRespVO">
|
|
select so.id, ms.scenic_id, device_id, url, ms.is_free, video_url, so.create_time, so.update_time,ms.is_buy
|
|
from member_source ms
|
|
left join source so on ms.source_id = so.id
|
|
|
|
where ms.member_id = #{userId} and ms.source_id = #{sourceId} and so.id is not null
|
|
limit 1
|
|
</select>
|
|
<select id="queryByRelation" resultType="com.ycwl.basic.model.pc.source.resp.SourceRespVO">
|
|
select so.id, ms.face_id, ms.scenic_id, ms.type, so.url, ms.is_free, so.create_time, so.update_time,ms.is_buy
|
|
from member_source ms
|
|
left join source so on ms.source_id = so.id
|
|
|
|
where
|
|
ms.member_id = #{memberId} and so.id
|
|
<if test="faceId!= null">and ms.face_id = #{faceId} </if>
|
|
<if test="type!=null">and ms.type = #{type} </if>
|
|
<if test="scenicId!= null">and ms.scenic_id = #{scenicId} </if>
|
|
<if test="isBuy!=null">and ms.is_buy = #{isBuy}</if>
|
|
order by so.create_time desc
|
|
</select>
|
|
<select id="querySameVideo" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select *
|
|
from source
|
|
where device_id = #{deviceId} and face_sample_id = #{faceSampleId} and type = 1
|
|
limit 1
|
|
</select>
|
|
<select id="hasRelationTo" resultType="java.lang.Integer">
|
|
select count(1)
|
|
from member_source
|
|
where member_id = #{memberId} and source_id = #{sourceId} and type = #{type}
|
|
</select>
|
|
<select id="listVideoByFaceRelation" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select s.*, ms.is_buy
|
|
from member_source ms
|
|
left join source s on ms.source_id = s.id
|
|
where ms.face_id = #{faceId} and ms.member_id = #{memberId} and ms.type = 1
|
|
order by create_time desc
|
|
</select>
|
|
<select id="listVideoByScenicFaceRelation" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select s.*, ms.is_buy
|
|
from member_source ms
|
|
left join source s on ms.source_id = s.id
|
|
where ms.face_id = #{faceId} and ms.type = 1 and ms.scenic_id = #{scenicId}
|
|
order by create_time desc
|
|
</select>
|
|
<select id="listImageByFaceRelation" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select s.*, ms.is_buy
|
|
from member_source ms
|
|
left join source s on ms.source_id = s.id
|
|
where ms.face_id = #{faceId} and ms.member_id = #{memberId} and ms.type = 2
|
|
</select>
|
|
<select id="getEntity" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select *
|
|
from source
|
|
where id = #{id}
|
|
</select>
|
|
<select id="listSourceWatermark" resultType="com.ycwl.basic.model.pc.source.entity.SourceWatermarkEntity">
|
|
select *
|
|
from source_watermark
|
|
where source_id in
|
|
<foreach collection="sourceIds" item="item" open="(" separator="," close=")">
|
|
#{item}
|
|
</foreach>
|
|
<if test="faceId == null">
|
|
and face_id is null
|
|
</if>
|
|
<if test="faceId != null">
|
|
and face_id = #{faceId}
|
|
</if>
|
|
and watermark_type = #{watermarkType}
|
|
</select>
|
|
<select id="countUser" resultType="java.lang.Integer">
|
|
select count(1)
|
|
from member_source ms
|
|
left join source so on ms.source_id = so.id
|
|
where
|
|
ms.member_id = #{memberId} and so.id is not null
|
|
<if test="scenicId!= null">and ms.scenic_id = #{scenicId} </if>
|
|
<if test="isBuy!=null">and ms.is_buy = #{isBuy} </if>
|
|
<if test="type!=null">and ms.type = #{type} </if>
|
|
<if test="faceId!=null">and ms.face_id = #{faceId} </if>
|
|
</select>
|
|
<select id="listByFaceRelation" resultType="com.ycwl.basic.model.pc.source.entity.MemberSourceEntity">
|
|
select *
|
|
from member_source ms
|
|
where ms.face_id = #{faceId}
|
|
<if test="type!=null">and ms.type = #{type} </if>
|
|
</select>
|
|
<update id="updateMemberIdByFaceId">
|
|
update member_source
|
|
set member_id = #{memberId}
|
|
where face_id = #{faceId}
|
|
</update>
|
|
<select id="listImageSourcesByFaceId" resultType="com.ycwl.basic.model.pc.source.entity.SourceEntity">
|
|
select s.*
|
|
from source s
|
|
inner join member_source ms on s.id = ms.source_id
|
|
where ms.face_id = #{faceId} and s.type = 2
|
|
</select>
|
|
</mapper>
|