ManagementInfoMapper.xml 29 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795
  1. <?xml version="1.0" encoding="UTF-8" ?>
  2. <!DOCTYPE mapper
  3. PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN"
  4. "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
  5. <mapper namespace="shop.alien.mapper.ManagementInfoMapper">
  6. <select id="getAllManagementInfo" resultType="shop.alien.entity.store.ManagementInfo">
  7. SELECT
  8. store.id AS store_id,
  9. store.store_name,
  10. IFNULL(meal.coupon_count, 0) AS meal_coupon_count,
  11. IFNULL(meal.order_count, 0) AS meal_order_count,
  12. ROUND(IFNULL(meal.order_amount, 0) / 100,2) AS meal_order_amount,
  13. IFNULL(meal.income_count, 0) AS meal_income_count,
  14. ROUND(IFNULL(meal.income_money, 0) / 100,2) AS meal_income_money,
  15. IFNULL(coupon.coupon_count, 0) AS coupon_coupon_count,
  16. IFNULL(coupon.order_count, 0) AS coupon_order_count,
  17. ROUND(IFNULL(coupon.order_amount, 0) / 100,2) AS coupon_order_amount,
  18. IFNULL(coupon.income_count, 0) AS coupon_income_count,
  19. ROUND(IFNULL(coupon.income_money, 0) / 100,2) AS coupon_income_money,
  20. ROUND(IFNULL(allInfo.cash_out_money, 0) / 100,2) AS cashout_money,
  21. ROUND(IFNULL(allInfo.account_frozen, 0) / 100,2) AS account_frozen
  22. FROM
  23. store_info store
  24. LEFT JOIN merchant_reconciliation_coupon coupon ON store.id = coupon.store_id
  25. LEFT JOIN merchant_reconciliation_meal meal ON store.id = meal.store_id
  26. LEFT JOIN merchant_reconciliation allInfo ON store.id = allInfo.store_id
  27. where 1 = 1
  28. <if test="storeName != null and storeName != ''">
  29. AND store.store_name LIKE CONCAT('%', #{storeName}, '%')
  30. </if>
  31. </select>
  32. <select id="getBillingRanking" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  33. SELECT
  34. store.id,
  35. store.store_name,
  36. ROUND(IFNULL( sum( money ), 0 ) / 100,2) AS income_money
  37. FROM
  38. store_info store
  39. LEFT JOIN ( SELECT * FROM store_income_details_record WHERE created_time > #{startDate} AND created_time &lt; #{endDate} ) income ON store.id = income.store_id
  40. GROUP BY
  41. store.id
  42. ORDER BY
  43. income_money DESC
  44. </select>
  45. <select id="getAmountPaid" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  46. SELECT
  47. ROUND(IFNULL(SUM( money ),0) / 100,2) AS amountPaid
  48. FROM
  49. store_cash_out_record cash
  50. WHERE
  51. created_time > #{startDate} AND created_time &lt; #{endDate}
  52. </select>
  53. <select id="getTotalTransactionAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  54. SELECT
  55. ROUND(IFNULL(SUM( money ),0) / 100,2) AS totalTransactionAmount
  56. FROM
  57. store_income_details_record income
  58. where
  59. 1 = 1
  60. <if test="storeId != null and storeId != ''">
  61. AND store_id = #{storeId}
  62. </if>
  63. </select>
  64. <select id="getTransactionAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  65. SELECT
  66. ROUND(IFNULL(SUM( money ),0) / 100,2) AS totalTransactionAmount
  67. FROM
  68. store_income_details_record income
  69. WHERE
  70. created_time > #{startDate} AND created_time &lt; #{endDate}
  71. </select>
  72. <select id="getTransactionNumber" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  73. SELECT
  74. COUNT(1) AS transactionNumber
  75. FROM
  76. store_cash_out_record cash
  77. WHERE
  78. created_time > #{startDate} AND created_time &lt; #{endDate}
  79. </select>
  80. <select id="getAllOrderAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  81. SELECT
  82. ROUND(IFNULL(SUM( final_price ),0) / 100,2) AS allOrderAmount
  83. FROM
  84. life_user_order
  85. where
  86. 1 = 1
  87. <if test="storeId != null and storeId != ''">
  88. AND store_id = #{storeId}
  89. </if>
  90. </select>
  91. <select id="getOrderAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  92. SELECT
  93. ROUND(IFNULL(SUM( final_price ),0),2) AS allOrderAmount
  94. FROM
  95. life_user_order
  96. where
  97. created_time > #{startDate} AND created_time &lt; #{endDate}
  98. </select>
  99. <select id="getAllWrittenOffAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  100. SELECT
  101. ROUND(IFNULL(SUM( money ),0) / 100,2) AS allWrittenOffAmount
  102. FROM
  103. store_income_details_record
  104. where
  105. 1 = 1
  106. <if test="storeId != null and storeId != ''">
  107. AND store_id = #{storeId}
  108. </if>
  109. </select>
  110. <select id="getWrittenOffAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  111. SELECT
  112. ROUND(IFNULL(SUM( money ),0) / 100,2) AS allWrittenOffAmount
  113. FROM
  114. store_income_details_record
  115. where
  116. created_time > #{startDate} AND created_time &lt; #{endDate}
  117. </select>
  118. <select id="getTotalWithdrawalAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  119. SELECT
  120. ROUND(IFNULL(SUM( money ),0) / 100,2) AS totalWithdrawalAmount
  121. FROM
  122. store_cash_out_record cash
  123. where
  124. 1 = 1
  125. <if test="storeId != null and storeId != ''">
  126. AND store_id = #{storeId}
  127. </if>
  128. </select>
  129. <select id="getWithdrawalAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  130. SELECT
  131. ROUND(IFNULL(SUM( money ),0) / 100,2) AS totalWithdrawalAmount
  132. FROM
  133. store_cash_out_record cash
  134. where payment_status = 1 and
  135. created_time > #{startDate} AND created_time &lt; #{endDate}
  136. </select>
  137. <select id="getStoreOrderDetail" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  138. SELECT
  139. userOrder.id,
  140. userOrder.user_id,
  141. userInfo.user_name,
  142. coupon.type,
  143. CASE
  144. type
  145. WHEN 1 THEN
  146. "代金券"
  147. WHEN 2 THEN
  148. "套餐"
  149. END AS type_name,
  150. coupon.`name`,
  151. "1" AS buy_count,
  152. ROUND(userOrder.price / 100,2) AS buy_amount,
  153. userOrder.buy_time AS buy_time,
  154. userOrder.used_time AS used_time,
  155. userOrder.refund_time AS refund_time,
  156. userOrder.`status` AS `status`,
  157. CASE
  158. coupon.STATUS
  159. WHEN 0 THEN
  160. "待使用"
  161. WHEN 1 THEN
  162. "已核销"
  163. WHEN 2 THEN
  164. "已过期"
  165. WHEN 3 THEN
  166. "待退款"
  167. WHEN 4 THEN
  168. "已退款"
  169. END AS status_name,
  170. userOrder.order_no
  171. FROM
  172. life_user_order userOrder
  173. LEFT JOIN life_coupon coupon ON coupon.id = userOrder.id
  174. LEFT JOIN life_user userInfo ON userOrder.user_id = userInfo.id
  175. WHERE
  176. userOrder.store_id = #{storeId}
  177. <if test = "orderNo != null and orderNo != ''" >
  178. AND userOrder.order_no = #{orderNo}
  179. </if >
  180. <if test = "userId != null and userId != ''" >
  181. AND userOrder.user_id = #{userId}
  182. </if >
  183. <if test = "userName != null and userName != ''" >
  184. AND userInfo.user_name like concat('%',#{userName},'%')
  185. </if >
  186. </select>
  187. <select id="getUserCount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  188. SELECT
  189. count( 1 ) AS user_count
  190. FROM
  191. ( SELECT DISTINCT user_id FROM life_user_order
  192. WHERE 1 = 1
  193. <if test = "storeId != null and storeId != ''" >
  194. AND store_id = #{storeId}
  195. </if >
  196. ) a
  197. </select>
  198. <select id="getOrderTransactionNumber" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  199. SELECT
  200. count( 1 ) AS order_transaction_number
  201. FROM
  202. life_user_order
  203. WHERE
  204. 1 = 1
  205. <if test = "storeId != null and storeId != ''" >
  206. AND store_id = #{storeId}
  207. </if >
  208. </select>
  209. <select id="getVerificationAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  210. SELECT
  211. ROUND(IFNULL(SUM(money),0) / 100,2) AS verification_amount
  212. FROM
  213. store_income_details_record
  214. WHERE 1 = 1
  215. <if test = "storeId != null and storeId != ''" >
  216. AND store_id = #{storeId}
  217. </if >
  218. </select>
  219. <select id="getApplicationForWithdrawal" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  220. SELECT
  221. cash.id AS cash_id,
  222. store.store_name AS store_name ,
  223. storeUser.phone AS store_phone ,
  224. store.id AS store_id,
  225. cash.cash_out_type,
  226. CASE
  227. cash.cash_out_type
  228. WHEN 0 THEN
  229. "手动提现"
  230. WHEN 1 THEN
  231. "到期自动提现"
  232. END AS cash_out_type_name,
  233. ROUND(IFNULL(cash.money, 0) / 100,2) AS money,
  234. cash.created_time,
  235. cash.payment_date,
  236. cash.approve_time,
  237. cash.pay_date,
  238. cash.fail_reason,
  239. cash.payment_status
  240. FROM
  241. store_cash_out_record cash
  242. LEFT JOIN store_info store ON cash.store_id = store.id
  243. LEFT JOIN store_user storeUser ON storeUser.store_id = store.id
  244. WHERE 1 = 1
  245. <if test = "storeId != null and storeId != ''" >
  246. AND cash.store_id = #{storeId}
  247. </if >
  248. <if test="storeName != null and storeName != ''">
  249. AND store.store_name LIKE CONCAT('%', #{storeName}, '%')
  250. </if>
  251. </select>
  252. <select id="getPlatformNetProfit" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  253. select IFNULL(ROUND(sum(all_data.platform_profit),2), 0) AS profit from
  254. (SELECT
  255. ROUND(SUM(final_price) * (IFNULL(store.commission_rate, 3)/100),2) AS platform_profit
  256. FROM
  257. life_user_order `order`
  258. LEFT JOIN store_info store ON store.id = `order`.store_id
  259. WHERE
  260. `status` = 2
  261. <if test="dataTime != null and dataTime != ''">
  262. AND
  263. `order`.used_time > #{dataTime}
  264. </if>
  265. GROUP BY
  266. store.id) all_data
  267. </select>
  268. <select id="getOrderQuantity" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  269. SELECT
  270. IFNULL(COUNT( 1 ) ,0) AS count
  271. FROM
  272. life_user_order
  273. WHERE
  274. ( `status` in (1, 2)
  275. <if test="dataTime != null and dataTime != ''">
  276. AND
  277. buy_time > #{dataTime}
  278. </if>
  279. )
  280. </select>
  281. <select id="getTradingVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  282. SELECT
  283. IFNULL(ROUND( sum( final_price ), 2 ),0) AS profit
  284. FROM
  285. life_user_order
  286. WHERE
  287. ( `status` = 2
  288. <if test="dataTime != null and dataTime != ''">
  289. AND
  290. used_time > #{dataTime}
  291. </if>
  292. )
  293. OR ( `status` = 1
  294. <if test="dataTime != null and dataTime != ''">
  295. AND
  296. buy_time > #{dataTime}
  297. </if>
  298. )
  299. </select>
  300. <select id="getQueryNetProfitDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  301. -- 使用递归 CTE 生成 1 到 23 的小时序列
  302. WITH RECURSIVE hours AS (
  303. SELECT 0 AS hour_num
  304. UNION ALL
  305. SELECT hour_num + 1
  306. FROM hours
  307. WHERE hour_num &lt; 23
  308. )
  309. SELECT
  310. concat(h.hour_num,":00") AS hour_num,
  311. COALESCE(ROUND(SUM(o.final_price) * 0.04, 2), 0) AS profit
  312. FROM
  313. hours h
  314. LEFT JOIN
  315. life_user_order o
  316. ON
  317. h.hour_num = HOUR(o.used_time)
  318. AND o.`status` = 1
  319. <if test="dataTime != null and dataTime != ''">
  320. AND o.used_time >= #{dataTime}
  321. </if>
  322. GROUP BY
  323. h.hour_num
  324. ORDER BY
  325. h.hour_num;
  326. </select>
  327. <select id="getQueryNetProfitWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  328. WITH RECURSIVE date_sequence AS (
  329. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  330. UNION ALL
  331. SELECT hour_num + INTERVAL 1 DAY
  332. FROM date_sequence
  333. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  334. )
  335. SELECT
  336. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  337. COALESCE(ROUND(SUM(luo.final_price) * 0.04, 2), 0) AS profit
  338. FROM
  339. date_sequence ds
  340. LEFT JOIN
  341. life_user_order luo
  342. ON
  343. luo.used_time >= ds.hour_num AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  344. AND luo.`status` = 1
  345. GROUP BY
  346. ds.hour_num
  347. ORDER BY
  348. ds.hour_num;
  349. </select>
  350. <select id="getQueryNetProfitMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  351. WITH RECURSIVE date_sequence AS (
  352. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  353. UNION ALL
  354. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  355. FROM date_sequence
  356. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  357. )
  358. SELECT
  359. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  360. COALESCE(ROUND(SUM(luo.final_price) * 0.04, 2), 0) AS profit
  361. FROM
  362. date_sequence ds
  363. LEFT JOIN
  364. life_user_order luo
  365. ON
  366. luo.used_time >= ds.hour_num AND luo.used_time &lt; DATE_ADD(ds.hour_num, INTERVAL 1 DAY)
  367. AND luo.`status` = 1
  368. GROUP BY
  369. ds.hour_num
  370. ORDER BY
  371. ds.hour_num;
  372. </select>
  373. <select id="getQueryNetProfitYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  374. WITH RECURSIVE month_sequence AS (
  375. SELECT 1 AS hour_num
  376. UNION ALL
  377. SELECT hour_num + 1
  378. FROM month_sequence
  379. WHERE hour_num &lt; 12
  380. )
  381. SELECT
  382. CONCAT(ms.hour_num,'月') AS hour_num,
  383. COALESCE(ROUND(SUM(luo.final_price) * 0.04, 2), 0) AS profit
  384. FROM
  385. month_sequence ms
  386. LEFT JOIN
  387. life_user_order luo
  388. ON
  389. MONTH(luo.used_time) = ms.hour_num
  390. AND YEAR(luo.used_time) = YEAR(#{dataTime})
  391. AND luo.`status` = 1
  392. GROUP BY
  393. ms.hour_num
  394. ORDER BY
  395. ms.hour_num;
  396. </select>
  397. <select id="getTradingVolumeDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  398. WITH RECURSIVE hours AS (
  399. SELECT 0 AS hour_num
  400. UNION ALL
  401. SELECT hour_num + 1
  402. FROM hours
  403. WHERE hour_num &lt; 23
  404. )
  405. SELECT
  406. concat(h.hour_num,":00") AS hour_num,
  407. COALESCE(ROUND(SUM(o.final_price), 2), 0) AS profit
  408. FROM
  409. hours h
  410. LEFT JOIN
  411. life_user_order o
  412. ON ( h.hour_num = HOUR( o.used_time ) AND ( o.`status` = 1 AND o.used_time >= #{dataTime} ) )
  413. OR ( h.hour_num = HOUR( o.buy_time ) AND ( o.`status` = 0 AND o.buy_time >= #{dataTime} ) )
  414. GROUP BY
  415. h.hour_num
  416. ORDER BY
  417. h.hour_num;
  418. </select>
  419. <select id="getTradingVolumeWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  420. WITH RECURSIVE date_sequence AS (
  421. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  422. UNION ALL
  423. SELECT hour_num + INTERVAL 1 DAY
  424. FROM date_sequence
  425. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  426. )
  427. SELECT
  428. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  429. COALESCE(ROUND(SUM(luo.final_price), 2), 0) AS profit
  430. FROM
  431. date_sequence ds
  432. LEFT JOIN
  433. life_user_order luo
  434. ON
  435. (luo.used_time >= ds.hour_num
  436. AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  437. AND luo.`status` = 1 )
  438. OR
  439. (luo.buy_time >= ds.hour_num
  440. AND luo.buy_time &lt; ds.hour_num + INTERVAL 1 DAY
  441. AND luo.`status` = 0 )
  442. GROUP BY
  443. ds.hour_num
  444. ORDER BY
  445. ds.hour_num;
  446. </select>
  447. <select id="getTradingVolumeMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  448. WITH RECURSIVE date_sequence AS (
  449. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  450. UNION ALL
  451. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  452. FROM date_sequence
  453. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  454. )
  455. SELECT
  456. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  457. COALESCE(ROUND(SUM(luo.final_price), 2), 0) AS profit
  458. FROM
  459. date_sequence ds
  460. LEFT JOIN
  461. life_user_order luo
  462. ON
  463. (luo.used_time >= ds.hour_num
  464. AND luo.used_time &lt; DATE_ADD( ds.hour_num, INTERVAL 1 DAY )
  465. AND luo.`status` = 1 )
  466. OR
  467. (luo.buy_time >= ds.hour_num
  468. AND luo.buy_time &lt; DATE_ADD( ds.hour_num, INTERVAL 1 DAY )
  469. AND luo.`status` = 0 )
  470. GROUP BY
  471. ds.hour_num
  472. ORDER BY
  473. ds.hour_num;
  474. </select>
  475. <select id="getTradingVolumeYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  476. WITH RECURSIVE month_sequence AS (
  477. SELECT 1 AS hour_num
  478. UNION ALL
  479. SELECT hour_num + 1
  480. FROM month_sequence
  481. WHERE hour_num &lt; 12
  482. )
  483. SELECT
  484. CONCAT(ms.hour_num,'月') AS hour_num,
  485. COALESCE(ROUND(SUM(luo.final_price), 2), 0) AS profit
  486. FROM
  487. month_sequence ms
  488. LEFT JOIN
  489. life_user_order luo
  490. ON
  491. (MONTH( luo.used_time ) = ms.hour_num
  492. AND YEAR( luo.used_time ) = YEAR( #{dataTime} )
  493. AND luo.`status` = 1 )
  494. OR
  495. (MONTH( luo.buy_time ) = ms.hour_num
  496. AND YEAR( luo.buy_time ) = YEAR( #{dataTime} )
  497. AND luo.`status` = 0 )
  498. GROUP BY
  499. ms.hour_num
  500. ORDER BY
  501. ms.hour_num;
  502. </select>
  503. <select id="getOrderQuantityDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  504. -- 使用 CTE 生成 0 到 23 的小时序列
  505. WITH hours AS (
  506. SELECT 0 AS hour_of_day
  507. UNION ALL SELECT 1
  508. UNION ALL SELECT 2
  509. UNION ALL SELECT 3
  510. UNION ALL SELECT 4
  511. UNION ALL SELECT 5
  512. UNION ALL SELECT 6
  513. UNION ALL SELECT 7
  514. UNION ALL SELECT 8
  515. UNION ALL SELECT 9
  516. UNION ALL SELECT 10
  517. UNION ALL SELECT 11
  518. UNION ALL SELECT 12
  519. UNION ALL SELECT 13
  520. UNION ALL SELECT 14
  521. UNION ALL SELECT 15
  522. UNION ALL SELECT 16
  523. UNION ALL SELECT 17
  524. UNION ALL SELECT 18
  525. UNION ALL SELECT 19
  526. UNION ALL SELECT 20
  527. UNION ALL SELECT 21
  528. UNION ALL SELECT 22
  529. UNION ALL SELECT 23
  530. )
  531. -- 主查询,左连接小时序列和原查询结果
  532. SELECT
  533. concat(h.hour_of_day,":00") AS hour_num,
  534. COALESCE(orders.order_count, 0) AS profit
  535. FROM
  536. hours h
  537. LEFT JOIN (
  538. SELECT
  539. HOUR(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END) AS hour_of_day,
  540. COUNT(*) AS order_count
  541. FROM
  542. life_user_order
  543. WHERE
  544. (
  545. `status` = 1
  546. AND used_time > #{dataTime}
  547. )
  548. OR (
  549. `status` = 0
  550. AND buy_time > #{dataTime}
  551. )
  552. GROUP BY
  553. HOUR(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END)
  554. ) orders ON h.hour_of_day = orders.hour_of_day
  555. ORDER BY
  556. h.hour_of_day;
  557. </select>
  558. <select id="getOrderQuantityWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  559. WITH RECURSIVE date_sequence AS (
  560. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  561. UNION ALL
  562. SELECT hour_num + INTERVAL 1 DAY
  563. FROM date_sequence
  564. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  565. )
  566. SELECT
  567. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  568. COALESCE(count(luo.id), 0) AS profit
  569. FROM
  570. date_sequence ds
  571. LEFT JOIN
  572. life_user_order luo
  573. ON
  574. (luo.used_time >= ds.hour_num AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  575. AND luo.`status` = 1) or
  576. (luo.buy_time >= ds.hour_num AND luo.buy_time &lt; ds.hour_num + INTERVAL 1 DAY
  577. AND luo.`status` = 0)
  578. GROUP BY
  579. ds.hour_num
  580. ORDER BY
  581. ds.hour_num;
  582. </select>
  583. <select id="getOrderQuantityMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  584. WITH RECURSIVE date_sequence AS (
  585. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  586. UNION ALL
  587. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  588. FROM date_sequence
  589. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  590. )
  591. SELECT
  592. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  593. COALESCE(count(luo.id), 0) AS profit
  594. FROM
  595. date_sequence ds
  596. LEFT JOIN
  597. life_user_order luo
  598. ON
  599. (luo.used_time >= ds.hour_num AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  600. AND luo.`status` = 1) or
  601. (luo.buy_time >= ds.hour_num AND luo.buy_time &lt; ds.hour_num + INTERVAL 1 DAY
  602. AND luo.`status` = 0)
  603. GROUP BY
  604. ds.hour_num
  605. ORDER BY
  606. ds.hour_num;
  607. </select>
  608. <select id="getOrderQuantityYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  609. WITH months AS (
  610. SELECT
  611. CONCAT(YEAR(#{dataTime}), '-', LPAD(seq, 2, '0')) AS month
  612. FROM (
  613. SELECT 1 AS seq UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL
  614. SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL
  615. SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9 UNION ALL
  616. SELECT 10 UNION ALL SELECT 11 UNION ALL SELECT 12
  617. ) seq
  618. )
  619. SELECT
  620. CONCAT(MONTH(STR_TO_DATE(m.MONTH, '%Y-%m')),'月') AS hour_num,
  621. COALESCE(orders.order_count, 0) AS profit
  622. FROM
  623. months m
  624. LEFT JOIN (
  625. SELECT
  626. DATE_FORMAT(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END, '%Y-%m') AS month,
  627. COUNT(*) AS order_count
  628. FROM
  629. life_user_order
  630. WHERE
  631. (
  632. `status` = 1
  633. AND used_time > #{dataTime}
  634. )
  635. OR (
  636. `status` = 0
  637. AND buy_time > #{dataTime}
  638. )
  639. GROUP BY
  640. DATE_FORMAT(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END, '%Y-%m')
  641. ) orders ON m.month = orders.month
  642. ORDER BY
  643. m.month;
  644. </select>
  645. <select id="getSalesVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  646. <!-- 初始化用户变量 -->
  647. SELECT
  648. profit,
  649. store.`store_name`
  650. FROM
  651. (
  652. SELECT
  653. count(id) AS profit,
  654. store_id
  655. FROM
  656. life_user_order
  657. WHERE
  658. ( `status` = 1 AND used_time >= #{startTime} AND used_time &lt; #{endTime})
  659. OR ( `status` = 0 AND buy_time >= #{startTime} AND buy_time &lt; #{endTime})
  660. GROUP BY
  661. store_id
  662. LIMIT 10
  663. ) statistic
  664. LEFT JOIN store_info store ON store.id = statistic.store_id
  665. ORDER BY
  666. profit DESC
  667. </select>
  668. <select id="getStorePlatformProfitDetails" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  669. SELECT
  670. store_id,
  671. store.store_name,
  672. ROUND(SUM(final_price), 2 ) AS operation_revenue,
  673. ROUND(SUM(final_price) - ROUND(SUM(final_price) * (IFNULL(store.commission_rate, 3)/100),2), 2) AS store_profit,
  674. ROUND(SUM(final_price) * (IFNULL(store.commission_rate, 3)/100),2) AS platform_profit
  675. FROM
  676. life_user_order `order`
  677. LEFT JOIN store_info store ON store.id = `order`.store_id
  678. WHERE
  679. `status` = 2
  680. <if test="startTime != null and startTime != ''" >
  681. AND used_time > #{startTime}
  682. </if>
  683. <if test="endTime != null and endTime != ''" >
  684. AND used_time &lt; #{endTime}
  685. </if>
  686. <if test="storeId != null and storeId != ''" >
  687. AND store_id like concat('%',#{storeId},'%')
  688. </if>
  689. <if test="storeName != null and storeName != ''" >
  690. AND store_name like concat('%',#{storeName},'%')
  691. </if>
  692. GROUP BY
  693. store.id
  694. ORDER BY
  695. `order`.created_time DESC
  696. </select>
  697. <select id="getRefundOrderQuantity" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  698. SELECT
  699. COUNT( 1 ) AS `count`
  700. FROM
  701. life_user_order
  702. WHERE
  703. `status` = 5
  704. <if test="dataTime != null and dataTime != ''">
  705. AND refund_time > #{dataTime}
  706. </if>
  707. </select>
  708. <select id="getTotalOrderVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  709. SELECT
  710. COUNT( 1 ) AS `count`
  711. FROM
  712. life_user_order `order`
  713. WHERE
  714. delete_flag = 0
  715. <if test="dataTime != null and dataTime != ''">
  716. AND buy_time > #{dataTime}
  717. </if>
  718. </select>
  719. <select id="getStorePlatformOrderVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  720. with total_coupon as(
  721. select id coupon_id,2 coupon_type,lgbm.group_name coupon_name, SUBSTRING_INDEX(image_id, ',', 1) AS image_id
  722. from life_group_buy_main lgbm where lgbm.delete_flag = 0
  723. union all
  724. select id coupon_id,1 coupon_type,lc.name coupon_name, SUBSTRING_INDEX(image_path, ',', 1) AS image_id
  725. from life_coupon lc where lc.delete_flag = 0
  726. )
  727. SELECT
  728. order_no,
  729. `order`.id as order_id,
  730. `order`.created_time AS order_time,
  731. `order`.finish_time AS finish_time,
  732. `order`.cancel_time AS cancel_time,
  733. `order`.pay_time AS pay_time,
  734. `order`.buy_time AS buy_time_str,
  735. ROUND(`order`.final_price, 2) AS final_price,
  736. CASE
  737. `order`.`status`
  738. WHEN 0 THEN '待支付'
  739. WHEN 1 THEN '已支付/待使用'
  740. WHEN 2 THEN '已核销'
  741. WHEN 3 THEN '已过期'
  742. WHEN 4 THEN '已取消'
  743. WHEN 5 THEN '已退款'
  744. WHEN 6 THEN '退款失败'
  745. WHEN 7 THEN '已完成'
  746. END AS status_name,
  747. simg.img_url,
  748. tc.*,
  749. store.store_name
  750. FROM
  751. life_user_order `order`
  752. left join store_info store on `order`.store_id = store.id
  753. left join order_coupon_middle ocm on ocm.order_id = `order`.id and ocm.delete_flag = 0
  754. inner join total_coupon tc on tc.coupon_id = ocm.coupon_id and tc.coupon_type = `order`.coupon_type
  755. left join store_img simg on simg.id = tc.image_id and simg.delete_flag = 0
  756. <where>
  757. 1 = 1
  758. <if test="orderType != null and orderType != ''">
  759. AND `order`.`status` = #{orderType}
  760. </if>
  761. <if test="startTime != null and startTime != ''">
  762. AND buy_time > #{startTime}
  763. </if>
  764. <if test="orderId != null and orderId != ''">
  765. AND `order`.`order_no` like concat('%',#{orderId},'%')
  766. </if>
  767. <if test="couponType != null and couponType != ''">
  768. AND tc.coupon_type = #{couponType}
  769. </if>
  770. <if test="couponName != null and couponName != ''">
  771. AND tc.coupon_name like concat('%',#{couponName},'%')
  772. </if>
  773. <if test="storeName != null and storeName != ''">
  774. AND store.store_name like concat('%',#{storeName},'%')
  775. </if>
  776. </where>
  777. ORDER BY
  778. `order`.created_time DESC
  779. </select>
  780. <select id="getRefundAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  781. SELECT
  782. IFNULL(ROUND( SUM( final_price ), 2 ),0) AS profit
  783. FROM
  784. life_user_order `order`
  785. WHERE
  786. `status` = 4
  787. <if test="dataTime != null and dataTime != ''" >
  788. AND `order`.refund_time > #{dataTime}
  789. </if>
  790. </select>
  791. </mapper>