Selaa lähdekoodia

refactor(system): 重构 AppSitePriceRulesMapper 查询逻辑

-优化了 theGymnasiumIsCharteredInfo 查询,增加了时间段有效性检查
- 改进了可用时间段的计算方法,考虑了当前日期和时间
- 优化了 SQL
SheepHy 1 viikko sitten
vanhempi
commit
825e1cf849

+ 57 - 44
national-motion-module-system/national-motion-system-biz/src/main/java/org/jeecg/modules/system/app/mapper/xml/AppSitePriceRulesMapper.xml

@@ -2,56 +2,69 @@
 <!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
 <mapper namespace="org.jeecg.modules.system.app.mapper.AppSitePriceRulesMapper">
     <select id="theGymnasiumIsCharteredInfo" resultType="org.jeecg.modules.app.vo.PlaceInfoVO$theGymnasiumIsCharteredInfoVO">
-<![CDATA[
-        WITH RECURSIVE dates AS (
-            SELECT
-                1 AS offset_day,
-                CURDATE() AS date_val,
-                WEEKDAY(CURDATE()) + 1 AS dow
-            UNION ALL
-            SELECT
-                offset_day + 1,
-                date_val + INTERVAL 1 DAY,
-            WEEKDAY(date_val + INTERVAL 1 DAY) + 1
-        FROM dates
-        WHERE offset_day < 7
-            ),
-            earliest_slots AS (
-        SELECT
-            r.id,
-            r.start_time,
-            r.end_time,
-            r.selling_price,
-            r.day_of_week,
-            ROW_NUMBER() OVER (
-            PARTITION BY r.day_of_week
-            ORDER BY r.selling_price ASC, r.start_time ASC
-            ) AS rn
-        FROM nm_site_price_rules r
-            LEFT JOIN nm_site_place sp ON r.site_place_id = sp.id
-        WHERE  r.org_code = #{orgCode}
-          AND r.category_id = #{categoryId}
-            )
+        <![CDATA[
+WITH RECURSIVE dates AS (
+    SELECT 1 AS offset_day, CURDATE() AS date_val, WEEKDAY(CURDATE()) + 1 AS dow
+    UNION ALL
+    SELECT offset_day + 1, date_val + INTERVAL 1 DAY, WEEKDAY(date_val + INTERVAL 1 DAY) + 1
+    FROM dates WHERE offset_day < 7
+),
+available_slots AS (
+    SELECT
+        r.id,
+        r.start_time,
+        r.end_time,
+        r.selling_price,
+        r.day_of_week,
+        r.date_of_sale,
+        ROW_NUMBER() OVER (
+            PARTITION BY COALESCE(r.date_of_sale, ADDDATE(CURDATE(), INTERVAL ((7 - WEEKDAY(CURDATE()) + (r.day_of_week - 1)) % 7) DAY))
+            ORDER BY r.start_time ASC
+        ) AS rn
+    FROM nm_site_price_rules r
+    LEFT JOIN nm_order_pro_info opi ON r.id = opi.product_id
+        AND opi.order_status IN (1, 2)
+        AND opi.use_date_str = COALESCE(
+            DATE_FORMAT(r.date_of_sale, '%Y-%m-%d'),
+            DATE_FORMAT(ADDDATE(CURDATE(), INTERVAL ((7 - WEEKDAY(CURDATE()) + (r.day_of_week - 1)) % 7) DAY), '%Y-%m-%d')
+        )
+    WHERE r.org_code = #{orgCode}
+        AND r.category_id = #{categoryId}
+        AND r.del_flag = 0
+        AND opi.product_id IS NULL
+        AND (
+        (r.date_of_sale IS NOT NULL AND (r.date_of_sale > CURDATE() OR (r.date_of_sale = CURDATE() AND r.start_time > CURRENT_TIME())))
+        OR
+        (r.date_of_sale IS NULL AND r.day_of_week IS NOT NULL AND (
+        ADDDATE(CURDATE(), INTERVAL ((7 - WEEKDAY(CURDATE()) + (r.day_of_week - 1)) % 7) DAY) > CURDATE()
+        OR (ADDDATE(CURDATE(), INTERVAL ((7 - WEEKDAY(CURDATE()) + (r.day_of_week - 1)) % 7) DAY) = CURDATE() AND r.start_time > CURRENT_TIME())
+        ))
+        )
+        -- 添加时间段有效性检查
+        AND (
+        (r.date_of_sale IS NOT NULL AND (r.date_of_sale > CURDATE() OR (r.date_of_sale = CURDATE() AND r.end_time > CURRENT_TIME())))
+        OR
+        (r.date_of_sale IS NULL AND ADDDATE(CURDATE(), INTERVAL ((7 - WEEKDAY(CURDATE()) + (r.day_of_week - 1)) % 7) DAY) > CURDATE())
+        OR
+        (r.date_of_sale IS NULL AND ADDDATE(CURDATE(), INTERVAL ((7 - WEEKDAY(CURDATE()) + (r.day_of_week - 1)) % 7) DAY) = CURDATE() AND r.end_time > CURRENT_TIME())
+        )
+        )
         SELECT
-            es.id AS id,
-            es.day_of_week,
-            es.start_time AS startTime,
-            CONCAT(es.start_time, '-', es.end_time) AS time_range,
-            es.selling_price AS sellingPrice,
+            asl.id,
+            asl.day_of_week,
+            asl.start_time AS startTime,
+            CONCAT(asl.start_time, '-', asl.end_time) AS time_range,
+            asl.selling_price AS sellingPrice,
             CASE
                 WHEN dm.offset_day = 1 THEN CONCAT('今天(', DATE_FORMAT(dm.date_val, '%m-%d'), ')')
                 WHEN dm.offset_day = 2 THEN CONCAT('明天(', DATE_FORMAT(dm.date_val, '%m-%d'), ')')
                 WHEN dm.offset_day = 3 THEN CONCAT('后天(', DATE_FORMAT(dm.date_val, '%m-%d'), ')')
-                ELSE CONCAT(
-                        ELT(dm.dow, '星期一', '星期二', '星期三', '星期四', '星期五', '星期六', '星期日'),
-                        '(',
-                        DATE_FORMAT(dm.date_val, '%m-%d'),
-                        ')'
-                     )
+                ELSE CONCAT(ELT(dm.dow, '星期一', '星期二', '星期三', '星期四', '星期五', '星期六', '星期日'), '(', DATE_FORMAT(dm.date_val, '%m-%d'), ')')
                 END AS date_label
-        FROM earliest_slots es
-                 JOIN dates dm ON es.day_of_week = dm.dow AND es.rn = 1
-        ORDER BY dm.offset_day
+        FROM available_slots asl
+                 JOIN dates dm ON COALESCE(asl.date_of_sale, ADDDATE(CURDATE(), INTERVAL ((7 - WEEKDAY(CURDATE()) + (asl.day_of_week - 1)) % 7) DAY)) = dm.date_val
+        WHERE asl.rn = 1
+        ORDER BY dm.offset_day;
         ]]>
     </select>
     <select id="timeSlot" resultType="org.jeecg.modules.app.vo.OrderVO$PreviewOrderPlaceSchoolChild">