ManagementInfoMapper.xml 33 KB

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