ManagementInfoMapper.xml 31 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840
  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) / 1000000,2) AS meal_order_amount,
  13. IFNULL(meal.income_count, 0) AS meal_income_count,
  14. ROUND(IFNULL(meal.income_money, 0) / 1000000,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) / 1000000,2) AS coupon_order_amount,
  18. IFNULL(coupon.income_count, 0) AS coupon_income_count,
  19. ROUND(IFNULL(coupon.income_money, 0) / 1000000,2) AS coupon_income_money,
  20. ROUND(IFNULL(allInfo.cash_out_money, 0) / 1000000,2) AS cashout_money,
  21. ROUND(IFNULL(allInfo.account_frozen, 0) / 1000000,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 ) / 1000000,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) / 100,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. cash.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
  254. IFNULL(ROUND(sum(final_price) * 0.04,2) ,0) AS profit
  255. FROM
  256. life_user_order
  257. WHERE
  258. `status` = 1
  259. <if test="dataTime != null and dataTime != ''">
  260. AND
  261. used_time > #{dataTime}
  262. </if>
  263. </select>
  264. <select id="getOrderQuantity" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  265. SELECT
  266. IFNULL(COUNT( 1 ) ,0) AS count
  267. FROM
  268. life_user_order
  269. WHERE
  270. ( `status` = 1
  271. <if test="dataTime != null and dataTime != ''">
  272. AND
  273. used_time > #{dataTime}
  274. </if>
  275. )
  276. OR ( `status` = 0
  277. <if test="dataTime != null and dataTime != ''">
  278. AND
  279. buy_time > #{dataTime}
  280. </if>
  281. )
  282. </select>
  283. <select id="getTradingVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  284. SELECT
  285. IFNULL(ROUND( sum( final_price ), 2 ),0) AS profit
  286. FROM
  287. life_user_order
  288. WHERE
  289. ( `status` = 1
  290. <if test="dataTime != null and dataTime != ''">
  291. AND
  292. used_time > #{dataTime}
  293. </if>
  294. )
  295. OR ( `status` = 0
  296. <if test="dataTime != null and dataTime != ''">
  297. AND
  298. buy_time > #{dataTime}
  299. </if>
  300. )
  301. </select>
  302. <select id="getQueryNetProfitDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  303. -- 使用递归 CTE 生成 1 到 23 的小时序列
  304. WITH RECURSIVE hours AS (
  305. SELECT 0 AS hour_num
  306. UNION ALL
  307. SELECT hour_num + 1
  308. FROM hours
  309. WHERE hour_num &lt; 23
  310. )
  311. SELECT
  312. concat(h.hour_num,":00") AS hour_num,
  313. COALESCE(ROUND(SUM(o.final_price) * 0.04, 2), 0) AS profit
  314. FROM
  315. hours h
  316. LEFT JOIN
  317. life_user_order o
  318. ON
  319. h.hour_num = HOUR(o.used_time)
  320. AND o.`status` = 1
  321. <if test="dataTime != null and dataTime != ''">
  322. AND o.used_time >= #{dataTime}
  323. </if>
  324. GROUP BY
  325. h.hour_num
  326. ORDER BY
  327. h.hour_num;
  328. </select>
  329. <select id="getQueryNetProfitWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  330. WITH RECURSIVE date_sequence AS (
  331. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  332. UNION ALL
  333. SELECT hour_num + INTERVAL 1 DAY
  334. FROM date_sequence
  335. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  336. )
  337. SELECT
  338. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  339. COALESCE(ROUND(SUM(luo.final_price) * 0.04, 2), 0) AS profit
  340. FROM
  341. date_sequence ds
  342. LEFT JOIN
  343. life_user_order luo
  344. ON
  345. luo.used_time >= ds.hour_num AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  346. AND luo.`status` = 1
  347. GROUP BY
  348. ds.hour_num
  349. ORDER BY
  350. ds.hour_num;
  351. </select>
  352. <select id="getQueryNetProfitMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  353. WITH RECURSIVE date_sequence AS (
  354. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  355. UNION ALL
  356. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  357. FROM date_sequence
  358. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  359. )
  360. SELECT
  361. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  362. COALESCE(ROUND(SUM(luo.final_price) * 0.04, 2), 0) AS profit
  363. FROM
  364. date_sequence ds
  365. LEFT JOIN
  366. life_user_order luo
  367. ON
  368. luo.used_time >= ds.hour_num AND luo.used_time &lt; DATE_ADD(ds.hour_num, INTERVAL 1 DAY)
  369. AND luo.`status` = 1
  370. GROUP BY
  371. ds.hour_num
  372. ORDER BY
  373. ds.hour_num;
  374. </select>
  375. <select id="getQueryNetProfitYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  376. WITH RECURSIVE month_sequence AS (
  377. SELECT 1 AS hour_num
  378. UNION ALL
  379. SELECT hour_num + 1
  380. FROM month_sequence
  381. WHERE hour_num &lt; 12
  382. )
  383. SELECT
  384. CONCAT(ms.hour_num,'月') AS hour_num,
  385. COALESCE(ROUND(SUM(luo.final_price) * 0.04, 2), 0) AS profit
  386. FROM
  387. month_sequence ms
  388. LEFT JOIN
  389. life_user_order luo
  390. ON
  391. MONTH(luo.used_time) = ms.hour_num
  392. AND YEAR(luo.used_time) = YEAR(#{dataTime})
  393. AND luo.`status` = 1
  394. GROUP BY
  395. ms.hour_num
  396. ORDER BY
  397. ms.hour_num;
  398. </select>
  399. <select id="getTradingVolumeDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  400. WITH RECURSIVE hours AS (
  401. SELECT 0 AS hour_num
  402. UNION ALL
  403. SELECT hour_num + 1
  404. FROM hours
  405. WHERE hour_num &lt; 23
  406. )
  407. SELECT
  408. concat(h.hour_num,":00") AS hour_num,
  409. COALESCE(ROUND(SUM(o.final_price), 2), 0) AS profit
  410. FROM
  411. hours h
  412. LEFT JOIN
  413. life_user_order o
  414. ON ( h.hour_num = HOUR( o.used_time ) AND ( o.`status` = 1 AND o.used_time >= #{dataTime} ) )
  415. OR ( h.hour_num = HOUR( o.buy_time ) AND ( o.`status` = 0 AND o.buy_time >= #{dataTime} ) )
  416. GROUP BY
  417. h.hour_num
  418. ORDER BY
  419. h.hour_num;
  420. </select>
  421. <select id="getTradingVolumeWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  422. WITH RECURSIVE date_sequence AS (
  423. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  424. UNION ALL
  425. SELECT hour_num + INTERVAL 1 DAY
  426. FROM date_sequence
  427. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  428. )
  429. SELECT
  430. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  431. COALESCE(ROUND(SUM(luo.final_price), 2), 0) AS profit
  432. FROM
  433. date_sequence ds
  434. LEFT JOIN
  435. life_user_order luo
  436. ON
  437. (luo.used_time >= ds.hour_num
  438. AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  439. AND luo.`status` = 1 )
  440. OR
  441. (luo.buy_time >= ds.hour_num
  442. AND luo.buy_time &lt; ds.hour_num + INTERVAL 1 DAY
  443. AND luo.`status` = 0 )
  444. GROUP BY
  445. ds.hour_num
  446. ORDER BY
  447. ds.hour_num;
  448. </select>
  449. <select id="getTradingVolumeMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  450. WITH RECURSIVE date_sequence AS (
  451. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  452. UNION ALL
  453. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  454. FROM date_sequence
  455. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  456. )
  457. SELECT
  458. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  459. COALESCE(ROUND(SUM(luo.final_price), 2), 0) AS profit
  460. FROM
  461. date_sequence ds
  462. LEFT JOIN
  463. life_user_order luo
  464. ON
  465. (luo.used_time >= ds.hour_num
  466. AND luo.used_time &lt; DATE_ADD( ds.hour_num, INTERVAL 1 DAY )
  467. AND luo.`status` = 1 )
  468. OR
  469. (luo.buy_time >= ds.hour_num
  470. AND luo.buy_time &lt; DATE_ADD( ds.hour_num, INTERVAL 1 DAY )
  471. AND luo.`status` = 0 )
  472. GROUP BY
  473. ds.hour_num
  474. ORDER BY
  475. ds.hour_num;
  476. </select>
  477. <select id="getTradingVolumeYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  478. WITH RECURSIVE month_sequence AS (
  479. SELECT 1 AS hour_num
  480. UNION ALL
  481. SELECT hour_num + 1
  482. FROM month_sequence
  483. WHERE hour_num &lt; 12
  484. )
  485. SELECT
  486. CONCAT(ms.hour_num,'月') AS hour_num,
  487. COALESCE(ROUND(SUM(luo.final_price), 2), 0) AS profit
  488. FROM
  489. month_sequence ms
  490. LEFT JOIN
  491. life_user_order luo
  492. ON
  493. (MONTH( luo.used_time ) = ms.hour_num
  494. AND YEAR( luo.used_time ) = YEAR( #{dataTime} )
  495. AND luo.`status` = 1 )
  496. OR
  497. (MONTH( luo.buy_time ) = ms.hour_num
  498. AND YEAR( luo.buy_time ) = YEAR( #{dataTime} )
  499. AND luo.`status` = 0 )
  500. GROUP BY
  501. ms.hour_num
  502. ORDER BY
  503. ms.hour_num;
  504. </select>
  505. <select id="getOrderQuantityDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  506. -- 使用 CTE 生成 0 到 23 的小时序列
  507. WITH hours AS (
  508. SELECT 0 AS hour_of_day
  509. UNION ALL SELECT 1
  510. UNION ALL SELECT 2
  511. UNION ALL SELECT 3
  512. UNION ALL SELECT 4
  513. UNION ALL SELECT 5
  514. UNION ALL SELECT 6
  515. UNION ALL SELECT 7
  516. UNION ALL SELECT 8
  517. UNION ALL SELECT 9
  518. UNION ALL SELECT 10
  519. UNION ALL SELECT 11
  520. UNION ALL SELECT 12
  521. UNION ALL SELECT 13
  522. UNION ALL SELECT 14
  523. UNION ALL SELECT 15
  524. UNION ALL SELECT 16
  525. UNION ALL SELECT 17
  526. UNION ALL SELECT 18
  527. UNION ALL SELECT 19
  528. UNION ALL SELECT 20
  529. UNION ALL SELECT 21
  530. UNION ALL SELECT 22
  531. UNION ALL SELECT 23
  532. )
  533. -- 主查询,左连接小时序列和原查询结果
  534. SELECT
  535. concat(h.hour_of_day,":00") AS hour_num,
  536. COALESCE(orders.order_count, 0) AS profit
  537. FROM
  538. hours h
  539. LEFT JOIN (
  540. SELECT
  541. HOUR(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END) AS hour_of_day,
  542. COUNT(*) AS order_count
  543. FROM
  544. life_user_order
  545. WHERE
  546. (
  547. `status` = 1
  548. AND used_time > #{dataTime}
  549. )
  550. OR (
  551. `status` = 0
  552. AND buy_time > #{dataTime}
  553. )
  554. GROUP BY
  555. HOUR(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END)
  556. ) orders ON h.hour_of_day = orders.hour_of_day
  557. ORDER BY
  558. h.hour_of_day;
  559. </select>
  560. <select id="getOrderQuantityWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  561. WITH RECURSIVE date_sequence AS (
  562. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  563. UNION ALL
  564. SELECT hour_num + INTERVAL 1 DAY
  565. FROM date_sequence
  566. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  567. )
  568. SELECT
  569. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  570. COALESCE(count(luo.id), 0) AS profit
  571. FROM
  572. date_sequence ds
  573. LEFT JOIN
  574. life_user_order luo
  575. ON
  576. (luo.used_time >= ds.hour_num AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  577. AND luo.`status` = 1) or
  578. (luo.buy_time >= ds.hour_num AND luo.buy_time &lt; ds.hour_num + INTERVAL 1 DAY
  579. AND luo.`status` = 0)
  580. GROUP BY
  581. ds.hour_num
  582. ORDER BY
  583. ds.hour_num;
  584. </select>
  585. <select id="getOrderQuantityMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  586. WITH RECURSIVE date_sequence AS (
  587. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  588. UNION ALL
  589. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  590. FROM date_sequence
  591. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  592. )
  593. SELECT
  594. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  595. COALESCE(count(luo.id), 0) AS profit
  596. FROM
  597. date_sequence ds
  598. LEFT JOIN
  599. life_user_order luo
  600. ON
  601. (luo.used_time >= ds.hour_num AND luo.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  602. AND luo.`status` = 1) or
  603. (luo.buy_time >= ds.hour_num AND luo.buy_time &lt; ds.hour_num + INTERVAL 1 DAY
  604. AND luo.`status` = 0)
  605. GROUP BY
  606. ds.hour_num
  607. ORDER BY
  608. ds.hour_num;
  609. </select>
  610. <select id="getOrderQuantityYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  611. WITH months AS (
  612. SELECT
  613. CONCAT(YEAR(#{dataTime}), '-', LPAD(seq, 2, '0')) AS month
  614. FROM (
  615. SELECT 1 AS seq UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL
  616. SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL
  617. SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9 UNION ALL
  618. SELECT 10 UNION ALL SELECT 11 UNION ALL SELECT 12
  619. ) seq
  620. )
  621. SELECT
  622. CONCAT(MONTH(STR_TO_DATE(m.MONTH, '%Y-%m')),'月') AS hour_num,
  623. COALESCE(orders.order_count, 0) AS profit
  624. FROM
  625. months m
  626. LEFT JOIN (
  627. SELECT
  628. DATE_FORMAT(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END, '%Y-%m') AS month,
  629. COUNT(*) AS order_count
  630. FROM
  631. life_user_order
  632. WHERE
  633. (
  634. `status` = 1
  635. AND used_time > #{dataTime}
  636. )
  637. OR (
  638. `status` = 0
  639. AND buy_time > #{dataTime}
  640. )
  641. GROUP BY
  642. DATE_FORMAT(CASE WHEN `status` = 1 THEN used_time ELSE buy_time END, '%Y-%m')
  643. ) orders ON m.month = orders.month
  644. ORDER BY
  645. m.month;
  646. </select>
  647. <select id="getSalesVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  648. <!-- 初始化用户变量 -->
  649. SELECT
  650. profit,
  651. store.`store_name`
  652. FROM
  653. (
  654. SELECT
  655. count(id) AS profit,
  656. store_id
  657. FROM
  658. life_user_order
  659. WHERE
  660. ( `status` = 1 AND used_time >= #{startTime} AND used_time &lt; #{endTime})
  661. OR ( `status` = 0 AND buy_time >= #{startTime} AND buy_time &lt; #{endTime})
  662. GROUP BY
  663. store_id
  664. LIMIT 10
  665. ) statistic
  666. LEFT JOIN store_info store ON store.id = statistic.store_id
  667. ORDER BY
  668. profit DESC
  669. </select>
  670. <select id="getStorePlatformProfitDetails" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  671. SELECT
  672. store_id,
  673. store.store_name,
  674. ROUND(SUM(final_price), 2 ) AS operation_revenue,
  675. ROUND(SUM(final_price) * 0.96,2) AS store_profit,
  676. ROUND(SUM(final_price) * 0.04,2) AS platform_profit
  677. FROM
  678. life_user_order `order`
  679. LEFT JOIN store_info store ON store.id = `order`.store_id
  680. WHERE
  681. `status` = 1
  682. <if test="startTime != null and startTime != ''" >
  683. AND used_time > #{startTime}
  684. </if>
  685. <if test="endTime != null and endTime != ''" >
  686. AND used_time &lt; #{endTime}
  687. </if>
  688. <if test="storeId != null and storeId != ''" >
  689. AND store_id like concat('%',#{storeId},'%')
  690. </if>
  691. GROUP BY
  692. store.id
  693. ORDER BY
  694. `order`.created_time DESC
  695. </select>
  696. <select id="getRefundOrderQuantity" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  697. SELECT
  698. COUNT( 1 ) AS `count`
  699. FROM
  700. life_user_order
  701. WHERE
  702. `status` = 4
  703. <if test="dataTime != null and dataTime != ''">
  704. AND refund_time > #{dataTime}
  705. </if>
  706. </select>
  707. <select id="getTotalOrderVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  708. SELECT
  709. COUNT( 1 ) AS `count`
  710. FROM
  711. life_user_order `order`
  712. WHERE
  713. 1 = 1
  714. AND (
  715. (`order`.`status` = 0
  716. <if test="dataTime != null and dataTime != ''">
  717. AND pay_time > #{dataTime}
  718. </if>
  719. )
  720. OR (`order`.`status` = 1
  721. <if test="dataTime != null and dataTime != ''">
  722. AND used_time > #{dataTime}
  723. </if>
  724. )
  725. OR (`order`.`status` = 4
  726. <if test="dataTime != null and dataTime != ''">
  727. AND refund_time > #{dataTime}
  728. </if>
  729. )
  730. OR (`order`.`status` = 3
  731. <if test="dataTime != null and dataTime != ''">
  732. AND refund_time > #{dataTime}
  733. </if>
  734. )
  735. OR (`order`.`status` = 99
  736. <if test="dataTime != null and dataTime != ''">
  737. AND `order`.created_time > #{dataTime}
  738. </if>
  739. )
  740. OR (`order`.`status` = 98
  741. <if test="dataTime != null and dataTime != ''">
  742. AND `order`.created_time > #{dataTime}
  743. </if>
  744. )
  745. )
  746. </select>
  747. <select id="getStorePlatformOrderVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  748. SELECT
  749. order_no,
  750. coupon.`name` AS order_name,
  751. `order`.created_time AS order_time,
  752. `order`.buy_time AS buy_time_str,
  753. ROUND(`order`.final_price, 2) AS final_price,
  754. CASE
  755. `order`.`status`
  756. WHEN 0 THEN '已付款'
  757. WHEN 1 THEN '已完成'
  758. WHEN 4 THEN '已退款'
  759. WHEN 99 THEN '待付款'
  760. WHEN 98 THEN '已取消'
  761. WHEN 3 THEN '待退款'
  762. END AS status_name
  763. FROM
  764. life_user_order `order`
  765. LEFT JOIN life_coupon coupon ON `order`.quan_id = coupon.id
  766. <where>
  767. 1 = 1
  768. <choose>
  769. <when test="orderType != null and orderType != ''">
  770. AND (`order`.`status` = #{orderType}
  771. <if test="orderType == 99">
  772. or `order`.`status` = "98"
  773. </if>
  774. )
  775. <choose>
  776. <when test="orderType == 0 and startTime != null and startTime != ''">AND pay_time > #{startTime}</when>
  777. <when test="orderType == 1 and startTime != null and startTime != ''">AND used_time > #{startTime}</when>
  778. <when test="orderType == 4 and startTime != null and startTime != ''">AND refund_time > #{startTime}</when>
  779. <when test="orderType == 3 and startTime != null and startTime != ''">AND refund_time > #{startTime}</when>
  780. <when test="orderType == 98 and startTime != null and startTime != ''">AND `order`.created_time > #{startTime}</when>
  781. <when test="orderType == 99 and startTime != null and startTime != ''">AND `order`.created_time > #{startTime}</when>
  782. </choose>
  783. </when>
  784. <otherwise>
  785. AND (
  786. (`order`.`status` = 0
  787. <if test="startTime != null and startTime != ''">
  788. AND pay_time > #{startTime}
  789. </if>
  790. )
  791. OR (`order`.`status` = 1
  792. <if test="startTime != null and startTime != ''">
  793. AND used_time > #{startTime}
  794. </if>
  795. )
  796. OR (`order`.`status` = 4
  797. <if test="startTime != null and startTime != ''">
  798. AND refund_time > #{startTime}
  799. </if>
  800. )
  801. OR (`order`.`status` = 3
  802. <if test="startTime != null and startTime != ''">
  803. AND refund_time > #{startTime}
  804. </if>
  805. )
  806. OR (`order`.`status` = 99
  807. <if test="startTime != null and startTime != ''">
  808. AND `order`.created_time > #{startTime}
  809. </if>
  810. )
  811. OR (`order`.`status` = 98
  812. <if test="startTime != null and startTime != ''">
  813. AND `order`.created_time > #{startTime}
  814. </if>
  815. )
  816. )
  817. </otherwise>
  818. </choose>
  819. <if test="orderId != null and orderId != ''">
  820. AND `order`.`order_no` like concat('%',#{orderId},'%')
  821. </if>
  822. </where>
  823. ORDER BY
  824. `order`.created_time DESC
  825. </select>
  826. <select id="getRefundAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  827. SELECT
  828. IFNULL(ROUND( SUM( final_price ), 2 ),0) AS profit
  829. FROM
  830. life_user_order `order`
  831. WHERE
  832. `status` = 4
  833. <if test="dataTime != null and dataTime != ''" >
  834. AND `order`.refund_time > #{dataTime}
  835. </if>
  836. </select>
  837. </mapper>