| 123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534 |
- <?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.zhentao.mapper.RecommendMapper">
- <resultMap id="RecommendUserMap" type="com.zhentao.vo.RecommendUserVO">
- <result column="user_id" property="userId"/>
- <result column="nickname" property="nickname"/>
- <result column="gender" property="gender"/>
- <result column="province_id" property="provinceId"/>
- <result column="city_id" property="cityId"/>
- <result column="area_id" property="areaId"/>
- <result column="height" property="height"/>
- <result column="weight" property="weight"/>
- <result column="education_level" property="educationLevel"/>
- <result column="salary_range" property="salaryRange"/>
- <result column="hobby" property="hobby"/>
- <result column="star" property="star"/>
- <result column="animal" property="animal"/>
- <result column="school_name" property="schoolName"/>
- <result column="job_title" property="jobTitle"/>
- <result column="avatar_url" property="avatarUrl"/>
- <result column="compatibility_score" property="compatibilityScore"/>
- <result column="last_active_at" property="lastActiveAt"/>
- </resultMap>
- <select id="selectRecommendedUsers" resultMap="RecommendUserMap">
- <![CDATA[
- SELECT
- u.user_id,
- u.nickname,
- u.gender,
- p.province_id,
- p.city_id,
- p.area_id,
- p.height,
- p.weight,
- p.education_level,
- p.salary_range,
- p.hobby,
- p.star,
- p.animal,
- p.school_name,
- p.job_title,
- u.avatar_url,
- (
- ROUND(
- (
- 1.0 * (COALESCE(p.authenticity_score, 0) / 100.0)
- + 0.9 * (
- CASE WHEN #{oppoOnly} = 1 AND u.gender <> cur.cu_gender THEN 1
- WHEN #{oppoOnly} = 0 THEN 1
- ELSE 0 END
- )
- + 0.8 * (
- CASE
- WHEN ABS(TIMESTAMPDIFF(YEAR, u.birth_date, cur.cu_birth)) <= 3 THEN 1
- WHEN ABS(TIMESTAMPDIFF(YEAR, u.birth_date, cur.cu_birth)) <= 5 THEN 0.5
- ELSE 0
- END
- )
- + 0.7 * LEAST(
- (
- CASE
- WHEN p.salary_range >= cur.cu_salary THEN 1
- WHEN p.salary_range = cur.cu_salary - 1 THEN 0.5
- ELSE 0
- END
- ),
- (
- CASE
- WHEN cur.cu_salary >= p.salary_range THEN 1
- WHEN cur.cu_salary = p.salary_range - 1 THEN 0.5
- ELSE 0
- END
- )
- )
- + 0.6 * LEAST(
- (
- CASE
- WHEN p.education_level >= cur.cu_edu THEN 1
- WHEN p.education_level = cur.cu_edu - 1 THEN 0.5
- ELSE 0
- END
- ),
- (
- CASE
- WHEN cur.cu_edu >= p.education_level THEN 1
- WHEN cur.cu_edu = p.education_level - 1 THEN 0.5
- ELSE 0
- END
- )
- )
- + 0.5 * (
- CASE
- WHEN p.height IS NOT NULL AND cur.cu_height IS NOT NULL THEN
- CASE
- WHEN ABS(p.height - cur.cu_height) <= 5 THEN 1
- WHEN ABS(p.height - cur.cu_height) <= 10 THEN 0.5
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.4 * (
- CASE WHEN JSON_OVERLAPS(p.hobby, cur.cu_hobby) THEN 1 ELSE 0 END
- )
- + 0.3 * (
- CASE WHEN p.city_id = cur.cu_city THEN 1
- WHEN p.province_id = cur.cu_province THEN 0.5 ELSE 0 END
- )
- + 0.2 * (
- CASE
- WHEN p.star IS NOT NULL AND cur.cu_star IS NOT NULL THEN
- CASE
- WHEN p.star = cur.cu_star THEN 1
- WHEN (
- (CASE
- WHEN p.star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN p.star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN p.star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN p.star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END)
- =
- (CASE
- WHEN cur.cu_star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN cur.cu_star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN cur.cu_star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN cur.cu_star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END)
- ) THEN 0.75
- WHEN (
- (
- (CASE
- WHEN p.star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN p.star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN p.star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN p.star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 1
- AND
- (CASE
- WHEN cur.cu_star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN cur.cu_star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN cur.cu_star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN cur.cu_star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 3
- ) OR (
- (CASE
- WHEN p.star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN p.star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN p.star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN p.star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 3
- AND
- (CASE
- WHEN cur.cu_star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN cur.cu_star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN cur.cu_star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN cur.cu_star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 1
- ) OR (
- (CASE
- WHEN p.star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN p.star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN p.star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN p.star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 2
- AND
- (CASE
- WHEN cur.cu_star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN cur.cu_star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN cur.cu_star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN cur.cu_star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 4
- ) OR (
- (CASE
- WHEN p.star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN p.star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN p.star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN p.star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 4
- AND
- (CASE
- WHEN cur.cu_star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN cur.cu_star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN cur.cu_star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN cur.cu_star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END) = 2
- )
- ) THEN 0.5
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.1 * (
- CASE
- WHEN p.animal IS NOT NULL AND cur.cu_animal IS NOT NULL THEN
- CASE
- WHEN p.animal = cur.cu_animal THEN 1
- WHEN (
- (CASE
- WHEN p.animal IN ('猴','鼠','龙') THEN 1
- WHEN p.animal IN ('猪','兔','羊') THEN 2
- WHEN p.animal IN ('虎','马','狗') THEN 3
- WHEN p.animal IN ('蛇','鸡','牛') THEN 4
- ELSE 0
- END)
- =
- (CASE
- WHEN cur.cu_animal IN ('猴','鼠','龙') THEN 1
- WHEN cur.cu_animal IN ('猪','兔','羊') THEN 2
- WHEN cur.cu_animal IN ('虎','马','狗') THEN 3
- WHEN cur.cu_animal IN ('蛇','鸡','牛') THEN 4
- ELSE 0
- END)
- ) THEN 0.75
- WHEN (
- (p.animal = '鼠' AND cur.cu_animal = '牛') OR (p.animal = '牛' AND cur.cu_animal = '鼠') OR
- (p.animal = '虎' AND cur.cu_animal = '猪') OR (p.animal = '猪' AND cur.cu_animal = '虎') OR
- (p.animal = '兔' AND cur.cu_animal = '狗') OR (p.animal = '狗' AND cur.cu_animal = '兔') OR
- (p.animal = '龙' AND cur.cu_animal = '鸡') OR (p.animal = '鸡' AND cur.cu_animal = '龙') OR
- (p.animal = '蛇' AND cur.cu_animal = '猴') OR (p.animal = '猴' AND cur.cu_animal = '蛇') OR
- (p.animal = '马' AND cur.cu_animal = '羊') OR (p.animal = '羊' AND cur.cu_animal = '马')
- ) THEN 0.75
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.05 * (
- CASE WHEN p.school_name IS NOT NULL AND cur.cu_school IS NOT NULL AND p.school_name = cur.cu_school THEN 1 ELSE 0 END
- )
- + 0.05 * (
- CASE
- WHEN p.job_title IS NOT NULL AND cur.cu_job_title IS NOT NULL THEN
- CASE
- WHEN p.job_title = cur.cu_job_title THEN 1
- WHEN p.job_title LIKE CONCAT('%', cur.cu_job_title, '%') OR cur.cu_job_title LIKE CONCAT('%', p.job_title, '%') THEN 0.5
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.05 * (
- CASE
- WHEN p.weight IS NOT NULL AND cur.cu_weight IS NOT NULL THEN
- CASE
- WHEN ABS(p.weight - cur.cu_weight) <= 5 THEN 1
- WHEN ABS(p.weight - cur.cu_weight) <= 10 THEN 0.5
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.05 * (
- CASE
- WHEN u.last_active_at >= NOW() - INTERVAL 7 DAY THEN 1
- WHEN u.last_active_at >= NOW() - INTERVAL 30 DAY THEN 0.4
- ELSE 0
- END
- )
- ) / 5.7 * 100
- , 2)
- ) AS compatibility_score,
- u.last_active_at
- FROM users u
- LEFT JOIN user_profile p ON p.user_id = u.user_id
- CROSS JOIN (
- SELECT
- u.user_id AS cu_id,
- u.gender AS cu_gender,
- u.birth_date AS cu_birth,
- COALESCE(up.city_id, NULL) AS cu_city,
- COALESCE(up.province_id, NULL) AS cu_province,
- COALESCE(up.height, NULL) AS cu_height,
- COALESCE(up.weight, NULL) AS cu_weight,
- COALESCE(up.education_level, NULL) AS cu_edu,
- COALESCE(up.salary_range, NULL) AS cu_salary,
- COALESCE(up.hobby, NULL) AS cu_hobby,
- COALESCE(up.star, NULL) AS cu_star,
- COALESCE(up.animal, NULL) AS cu_animal,
- COALESCE(up.school_name, NULL) AS cu_school,
- COALESCE(up.job_title, NULL) AS cu_job_title
- FROM users u
- LEFT JOIN user_profile up ON up.user_id = u.user_id
- WHERE u.user_id = #{userId}
- AND u.gender IS NOT NULL
- AND u.gender <> 0
- ) cur
- WHERE cur.cu_id IS NOT NULL
- AND cur.cu_gender IS NOT NULL
- AND cur.cu_gender <> 0
- AND u.user_id <> cur.cu_id
- AND u.status = 1
- AND u.gender IS NOT NULL
- AND u.gender <> 0
- AND (
- #{oppoOnly} = 0
- OR u.gender <> cur.cu_gender
- )
- ORDER BY compatibility_score DESC, u.last_active_at DESC
- LIMIT #{limit}
- ]]>
- </select>
-
- <select id="selectByRules" resultMap="RecommendUserMap">
- SELECT
- u.user_id,
- u.nickname,
- u.gender,
- u.avatar_url,
- p.province_id,
- p.city_id,
- p.area_id,
- p.height,
- p.education_level,
- p.salary_range,
- p.star,
- p.animal,
- p.hobby,
- (
- ROUND(
- (
- 1.0 * (COALESCE(p.authenticity_score, 0) / 100.0)
- + 0.9 * (
- CASE WHEN u.gender <> cur.cu_gender THEN 1 ELSE 0.2 END
- ) /* 不同性别权重更高,相同性别给予较低分 */
- + 0.8 * (
- CASE
- WHEN ABS(TIMESTAMPDIFF(YEAR, u.birth_date, cur.cu_birth)) <= 3 THEN 1
- WHEN ABS(TIMESTAMPDIFF(YEAR, u.birth_date, cur.cu_birth)) <= 5 THEN 0.5
- ELSE 0
- END
- )
- + 0.7 * LEAST(
- (
- CASE
- WHEN p.salary_range >= cur.cu_salary THEN 1
- WHEN p.salary_range = cur.cu_salary - 1 THEN 0.5
- ELSE 0
- END
- ),
- (
- CASE
- WHEN cur.cu_salary >= p.salary_range THEN 1
- WHEN cur.cu_salary = p.salary_range - 1 THEN 0.5
- ELSE 0
- END
- )
- )
- + 0.6 * LEAST(
- (
- CASE
- WHEN p.education_level >= cur.cu_edu THEN 1
- WHEN p.education_level = cur.cu_edu - 1 THEN 0.5
- ELSE 0
- END
- ),
- (
- CASE
- WHEN cur.cu_edu >= p.education_level THEN 1
- WHEN cur.cu_edu = p.education_level - 1 THEN 0.5
- ELSE 0
- END
- )
- )
- + 0.5 * (
- CASE
- WHEN p.height IS NOT NULL AND cur.cu_height IS NOT NULL THEN
- CASE
- WHEN ABS(p.height - cur.cu_height) <= 5 THEN 1
- WHEN ABS(p.height - cur.cu_height) <= 10 THEN 0.5
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.4 * (
- CASE WHEN JSON_OVERLAPS(p.hobby, cur.cu_hobby) THEN 1 ELSE 0 END
- )
- + 0.3 * (
- CASE WHEN p.city_id = cur.cu_city THEN 1
- WHEN p.province_id = cur.cu_province THEN 0.5 ELSE 0 END
- )
- + 0.2 * (
- CASE
- WHEN p.star IS NOT NULL AND cur.cu_star IS NOT NULL THEN
- CASE
- WHEN p.star = cur.cu_star THEN 1
- WHEN (
- (CASE
- WHEN p.star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN p.star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN p.star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN p.star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END)
- =
- (CASE
- WHEN cur.cu_star IN ('白羊座','狮子座','射手座') THEN 1
- WHEN cur.cu_star IN ('金牛座','处女座','摩羯座') THEN 2
- WHEN cur.cu_star IN ('双子座','天秤座','水瓶座') THEN 3
- WHEN cur.cu_star IN ('巨蟹座','天蝎座','双鱼座') THEN 4
- ELSE 0
- END)
- ) THEN 0.75
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.1 * (
- CASE
- WHEN p.animal IS NOT NULL AND cur.cu_animal IS NOT NULL THEN
- CASE WHEN p.animal = cur.cu_animal THEN 1 ELSE 0 END
- ELSE 0
- END
- )
- + 0.05 * (
- CASE WHEN p.school_name IS NOT NULL AND cur.cu_school IS NOT NULL AND p.school_name = cur.cu_school THEN 1 ELSE 0 END
- )
- + 0.05 * (
- CASE
- WHEN p.job_title IS NOT NULL AND cur.cu_job_title IS NOT NULL THEN
- CASE
- WHEN p.job_title = cur.cu_job_title THEN 1
- WHEN p.job_title LIKE CONCAT('%', cur.cu_job_title, '%') OR cur.cu_job_title LIKE CONCAT('%', p.job_title, '%') THEN 0.5
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.05 * (
- CASE
- WHEN p.weight IS NOT NULL AND cur.cu_weight IS NOT NULL THEN
- CASE
- WHEN ABS(p.weight - cur.cu_weight) <= 5 THEN 1
- WHEN ABS(p.weight - cur.cu_weight) <= 10 THEN 0.5
- ELSE 0
- END
- ELSE 0
- END
- )
- + 0.05 * (
- CASE
- WHEN u.last_active_at >= NOW() - INTERVAL 7 DAY THEN 1
- WHEN u.last_active_at >= NOW() - INTERVAL 30 DAY THEN 0.4
- ELSE 0
- END
- )
- ) / 5.7 * 100
- , 2)
- ) AS compatibility_score
- FROM users u
- JOIN user_profile p ON p.user_id = u.user_id
- CROSS JOIN (
- SELECT
- u.user_id AS cu_id,
- u.gender AS cu_gender,
- u.birth_date AS cu_birth,
- up.city_id AS cu_city,
- up.province_id AS cu_province,
- up.height AS cu_height,
- up.weight AS cu_weight,
- up.education_level AS cu_edu,
- up.salary_range AS cu_salary,
- up.hobby AS cu_hobby,
- up.star AS cu_star,
- up.animal AS cu_animal,
- up.school_name AS cu_school,
- up.job_title AS cu_job_title
- FROM users u
- LEFT JOIN user_profile up ON up.user_id = u.user_id
- WHERE u.user_id = #{q.userId}
- ) cur
- <where>
- u.status = 1
- AND u.gender IS NOT NULL
- AND u.gender <> 0
- <if test="q.userId != null">AND u.user_id <> #{q.userId}</if>
- AND (
- (#{q.gender} IS NOT NULL AND u.gender = #{q.gender})
- OR (#{q.gender} IS NULL AND (cur.cu_gender IS NOT NULL AND cur.cu_gender <> 0 AND u.gender <> cur.cu_gender))
- )
- <if test="q.provinceId != null">AND p.province_id = #{q.provinceId}</if>
- <if test="q.cityId != null">AND p.city_id = #{q.cityId}</if>
- <if test="q.areaId != null">AND p.area_id = #{q.areaId}</if>
- <if test="q.heightMin != null">AND p.height >= #{q.heightMin}</if>
- <if test="q.heightMax != null">AND p.height <= #{q.heightMax}</if>
- <if test="q.educationMin != null">AND p.education_level >= #{q.educationMin}</if>
- <if test="q.salaryMin != null">AND p.salary_range >= #{q.salaryMin}</if>
- <if test="q.star != null">AND p.star = #{q.star}</if>
- <if test="q.animal != null">AND p.animal = #{q.animal}</if>
- <if test="hobbyJson != null">AND JSON_OVERLAPS(p.hobby, #{hobbyJson})</if>
- <if test="birthMin != null">AND u.birth_date >= #{birthMin}</if>
- <if test="birthMax != null">AND u.birth_date <= #{birthMax}</if>
- <if test="excludeIds != null and excludeIds.size() > 0">
- AND u.user_id NOT IN
- <foreach collection="excludeIds" item="id" open="(" separator="," close=")">#{id}</foreach>
- </if>
- </where>
- ORDER BY compatibility_score DESC, u.last_active_at DESC
- LIMIT #{limit} OFFSET #{offset}
- </select>
- <select id="selectAllProvinces" resultType="com.zhentao.pojo.Province">
- SELECT id, name FROM province ORDER BY id
- </select>
- <select id="selectAllCities" resultType="com.zhentao.pojo.City">
- SELECT id, name, province_id FROM city ORDER BY id
- </select>
- <select id="selectCitiesByProvince" resultType="com.zhentao.pojo.City">
- SELECT id, name, province_id FROM city WHERE province_id = #{provinceId} ORDER BY id
- </select>
- <select id="selectAreasByCity" resultType="com.zhentao.pojo.Area">
- SELECT id, name, city_id FROM area WHERE city_id = #{cityId} ORDER BY id
- </select>
- </mapper>
|