ManagementInfoMapper.xml 35 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977
  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. </select>
  254. <select id="getCashOutDetail" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  255. SELECT
  256. cash.id AS cash_id,
  257. store.store_name AS store_name ,
  258. storeUser.phone AS store_phone ,
  259. store.id AS store_id,
  260. cash.cash_out_type,
  261. CASE
  262. cash.cash_out_type
  263. WHEN 0 THEN
  264. "手动提现"
  265. WHEN 1 THEN
  266. "到期自动提现"
  267. END AS cash_out_type_name,
  268. ROUND(IFNULL(cash.money, 0) / 100,2) AS money,
  269. cash.created_time,
  270. cash.payment_date,
  271. cash.approve_time,
  272. cash.pay_date,
  273. cash.fail_reason,
  274. cash.payment_status,
  275. cash.approve_fail_reason
  276. FROM
  277. store_cash_out_record cash
  278. LEFT JOIN store_info store ON cash.store_id = store.id
  279. LEFT JOIN store_user storeUser ON storeUser.store_id = store.id
  280. WHERE cash.id = #{id}
  281. </select>
  282. <select id="getPlatformNetProfit" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  283. select IFNULL(ROUND(sum(all_data.platform_profit),2), 0) AS profit from
  284. (SELECT
  285. ROUND(SUM(final_price) * (IFNULL(store.commission_rate, 3)/100),2) AS platform_profit
  286. FROM
  287. life_user_order `order`
  288. LEFT JOIN store_info store ON store.id = `order`.store_id
  289. left join order_coupon_middle ocm on ocm.order_id = `order`.id
  290. WHERE
  291. `order`.`status` = 2
  292. <if test="dataTime != null and dataTime != ''">
  293. AND
  294. ocm.used_time > #{dataTime}
  295. </if>
  296. GROUP BY
  297. store.id) all_data
  298. </select>
  299. <select id="getOrderQuantity" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  300. select count(*) count from (
  301. SELECT
  302. IFNULL(COUNT( 1 ) ,0) AS count
  303. FROM
  304. life_user_order `order`
  305. left join order_coupon_middle ocm on ocm.order_id = `order`.id
  306. WHERE
  307. ( `order`.`status` = 1
  308. <if test="dataTime != null and dataTime != ''">
  309. AND
  310. `order`.pay_time > #{dataTime}
  311. </if>
  312. ) or
  313. ( `order`.`status` = 2
  314. <if test="dataTime != null and dataTime != ''">
  315. AND
  316. ocm.used_time > #{dataTime}
  317. </if>
  318. )
  319. GROUP BY
  320. `order`.id ) all_data
  321. </select>
  322. <select id="getTradingVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  323. select IFNULL(ROUND(sum(all_data.profit_a), 2 ),0) profit from (
  324. SELECT
  325. IFNULL(ROUND( `order`.final_price , 2 ),0) AS profit_a
  326. FROM
  327. life_user_order `order`
  328. left join order_coupon_middle ocm on ocm.order_id = `order`.id
  329. WHERE
  330. ( `order`.`status` = 2
  331. <if test="dataTime != null and dataTime != ''">
  332. AND
  333. ocm.used_time > #{dataTime}
  334. </if>
  335. )
  336. OR ( `order`.`status` = 1
  337. <if test="dataTime != null and dataTime != ''">
  338. AND
  339. `order`.pay_time > #{dataTime}
  340. </if>
  341. ) ) all_data
  342. </select>
  343. <select id="getQueryNetProfitDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  344. -- 使用递归 CTE 生成 1 到 23 的小时序列
  345. WITH RECURSIVE hours AS (
  346. SELECT 0 AS hour_num
  347. UNION ALL
  348. SELECT hour_num + 1
  349. FROM hours
  350. WHERE hour_num &lt; 23
  351. ),
  352. order_data AS (
  353. SELECT
  354. o.id,
  355. si.commission_rate,
  356. o.final_price,
  357. ocm.used_time
  358. FROM life_user_order o
  359. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  360. LEFT JOIN store_info si ON si.id = o.store_id
  361. WHERE o.delete_flag = 0 and o.status = 2
  362. <if test="dataTime != null and dataTime != ''">
  363. AND ocm.used_time >= #{dataTime}
  364. </if>
  365. )
  366. SELECT
  367. concat(h.hour_num,":00") AS hour_num,
  368. COALESCE(ROUND(SUM(o.final_price) * (IFNULL(o.commission_rate, 3)/100), 2), 0) AS profit
  369. FROM
  370. hours h
  371. LEFT JOIN order_data o ON h.hour_num = HOUR(o.used_time)
  372. GROUP BY
  373. h.hour_num
  374. ORDER BY
  375. h.hour_num;
  376. </select>
  377. <select id="getQueryNetProfitWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  378. WITH RECURSIVE date_sequence AS (
  379. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  380. UNION ALL
  381. SELECT hour_num + INTERVAL 1 DAY
  382. FROM date_sequence
  383. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  384. ),
  385. order_data AS (
  386. SELECT
  387. o.id,
  388. si.commission_rate,
  389. o.final_price,
  390. ocm.used_time
  391. FROM life_user_order o
  392. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  393. LEFT JOIN store_info si ON si.id = o.store_id
  394. WHERE o.delete_flag = 0 and o.status = 2
  395. )
  396. SELECT
  397. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  398. COALESCE(ROUND(SUM(o.final_price) * (IFNULL(o.commission_rate, 3)/100), 2), 0) AS profit
  399. FROM
  400. date_sequence ds
  401. LEFT JOIN order_data o ON
  402. o.used_time >= ds.hour_num
  403. AND o.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  404. GROUP BY
  405. ds.hour_num
  406. ORDER BY
  407. ds.hour_num;
  408. </select>
  409. <select id="getQueryNetProfitMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  410. WITH RECURSIVE date_sequence AS (
  411. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  412. UNION ALL
  413. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  414. FROM date_sequence
  415. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  416. ),
  417. order_data AS (
  418. SELECT
  419. o.id,
  420. si.commission_rate,
  421. o.final_price,
  422. ocm.used_time
  423. FROM life_user_order o
  424. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  425. LEFT JOIN store_info si ON si.id = o.store_id
  426. WHERE o.delete_flag = 0 and o.status = 2
  427. )
  428. SELECT
  429. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  430. COALESCE(ROUND(SUM(o.final_price) * (IFNULL(o.commission_rate, 3)/100), 2), 0) AS profit
  431. FROM
  432. date_sequence ds
  433. LEFT JOIN order_data o ON
  434. o.used_time >= ds.hour_num AND o.used_time &lt; DATE_ADD(ds.hour_num, INTERVAL 1 DAY)
  435. GROUP BY
  436. ds.hour_num
  437. ORDER BY
  438. ds.hour_num;
  439. </select>
  440. <select id="getQueryNetProfitYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  441. WITH RECURSIVE month_sequence AS (
  442. SELECT 1 AS hour_num
  443. UNION ALL
  444. SELECT hour_num + 1
  445. FROM month_sequence
  446. WHERE hour_num &lt; 12
  447. ),
  448. order_data AS (
  449. SELECT
  450. o.id,
  451. si.commission_rate,
  452. o.final_price,
  453. ocm.used_time
  454. FROM life_user_order o
  455. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  456. LEFT JOIN store_info si ON si.id = o.store_id
  457. WHERE o.delete_flag = 0 and o.status = 2
  458. )
  459. SELECT
  460. CONCAT(ms.hour_num,'月') AS hour_num,
  461. COALESCE(ROUND(SUM(o.final_price) * (IFNULL(o.commission_rate, 3)/100), 2), 0) AS profit
  462. FROM
  463. month_sequence ms
  464. LEFT JOIN order_data o ON
  465. MONTH(o.used_time) = ms.hour_num
  466. AND YEAR(o.used_time) = YEAR(#{dataTime})
  467. GROUP BY
  468. ms.hour_num
  469. ORDER BY
  470. ms.hour_num;
  471. </select>
  472. <select id="getTradingVolumeDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  473. WITH RECURSIVE hours AS (
  474. SELECT 0 AS hour_num
  475. UNION ALL
  476. SELECT hour_num + 1
  477. FROM hours
  478. WHERE hour_num &lt; 23
  479. ),
  480. order_data AS (
  481. SELECT
  482. o.id,
  483. si.commission_rate,
  484. o.final_price,
  485. ocm.used_time,
  486. o.pay_time,
  487. o.status
  488. FROM life_user_order o
  489. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  490. LEFT JOIN store_info si ON si.id = o.store_id
  491. WHERE o.delete_flag = 0
  492. )
  493. SELECT
  494. concat(h.hour_num,":00") AS hour_num,
  495. COALESCE(ROUND(SUM(o.final_price), 2), 0) AS profit
  496. FROM
  497. hours h
  498. LEFT JOIN order_data o
  499. ON ( h.hour_num = HOUR( o.used_time ) AND ( o.`status` = 2 AND o.used_time >= #{dataTime} ) )
  500. OR ( h.hour_num = HOUR( o.pay_time ) AND ( o.`status` = 1 AND o.pay_time >= #{dataTime} ) )
  501. GROUP BY
  502. h.hour_num
  503. ORDER BY
  504. h.hour_num;
  505. </select>
  506. <select id="getTradingVolumeWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  507. WITH RECURSIVE date_sequence AS (
  508. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  509. UNION ALL
  510. SELECT hour_num + INTERVAL 1 DAY
  511. FROM date_sequence
  512. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  513. ),
  514. order_data AS (
  515. SELECT
  516. o.id,
  517. si.commission_rate,
  518. o.final_price,
  519. ocm.used_time,
  520. o.pay_time,
  521. o.status
  522. FROM life_user_order o
  523. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  524. LEFT JOIN store_info si ON si.id = o.store_id
  525. WHERE o.delete_flag = 0
  526. )
  527. SELECT
  528. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  529. COALESCE(ROUND(SUM(o.final_price), 2), 0) AS profit
  530. FROM
  531. date_sequence ds
  532. LEFT JOIN
  533. order_data o
  534. ON
  535. (o.used_time >= ds.hour_num
  536. AND o.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  537. AND o.`status` = 2 )
  538. OR
  539. (o.pay_time >= ds.hour_num
  540. AND o.pay_time &lt; ds.hour_num + INTERVAL 1 DAY
  541. AND o.`status` = 1 )
  542. GROUP BY
  543. ds.hour_num
  544. ORDER BY
  545. ds.hour_num;
  546. </select>
  547. <select id="getTradingVolumeMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  548. WITH RECURSIVE date_sequence AS (
  549. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  550. UNION ALL
  551. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  552. FROM date_sequence
  553. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  554. ),
  555. order_data AS (
  556. SELECT
  557. o.id,
  558. si.commission_rate,
  559. o.final_price,
  560. ocm.used_time,
  561. o.pay_time,
  562. o.status
  563. FROM life_user_order o
  564. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  565. LEFT JOIN store_info si ON si.id = o.store_id
  566. WHERE o.delete_flag = 0
  567. )
  568. SELECT
  569. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  570. COALESCE(ROUND(SUM(o.final_price), 2), 0) AS profit
  571. FROM
  572. date_sequence ds
  573. LEFT JOIN
  574. order_data o
  575. ON
  576. (o.used_time >= ds.hour_num
  577. AND o.used_time &lt; DATE_ADD( ds.hour_num, INTERVAL 1 DAY )
  578. AND o.`status` = 2 )
  579. OR
  580. (o.pay_time >= ds.hour_num
  581. AND o.pay_time &lt; DATE_ADD( ds.hour_num, INTERVAL 1 DAY )
  582. AND o.`status` = 1 )
  583. GROUP BY
  584. ds.hour_num
  585. ORDER BY
  586. ds.hour_num;
  587. </select>
  588. <select id="getTradingVolumeYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  589. WITH RECURSIVE month_sequence AS (
  590. SELECT 1 AS hour_num
  591. UNION ALL
  592. SELECT hour_num + 1
  593. FROM month_sequence
  594. WHERE hour_num &lt; 12
  595. ),
  596. order_data AS (
  597. SELECT
  598. o.id,
  599. si.commission_rate,
  600. o.final_price,
  601. ocm.used_time,
  602. o.pay_time,
  603. o.status
  604. FROM life_user_order o
  605. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  606. LEFT JOIN store_info si ON si.id = o.store_id
  607. WHERE o.delete_flag = 0
  608. )
  609. SELECT
  610. CONCAT(ms.hour_num,'月') AS hour_num,
  611. COALESCE(ROUND(SUM(o.final_price), 2), 0) AS profit
  612. FROM
  613. month_sequence ms
  614. LEFT JOIN
  615. order_data o
  616. ON
  617. (MONTH( o.used_time ) = ms.hour_num
  618. AND YEAR( o.used_time ) = YEAR( #{dataTime} )
  619. AND o.`status` = 1 )
  620. OR
  621. (MONTH( o.pay_time ) = ms.hour_num
  622. AND YEAR( o.pay_time ) = YEAR( #{dataTime} )
  623. AND o.`status` = 0 )
  624. GROUP BY
  625. ms.hour_num
  626. ORDER BY
  627. ms.hour_num;
  628. </select>
  629. <select id="getOrderQuantityDay" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  630. -- 使用 CTE 生成 0 到 23 的小时序列
  631. WITH hours AS (
  632. SELECT 0 AS hour_of_day
  633. UNION ALL SELECT 1
  634. UNION ALL SELECT 2
  635. UNION ALL SELECT 3
  636. UNION ALL SELECT 4
  637. UNION ALL SELECT 5
  638. UNION ALL SELECT 6
  639. UNION ALL SELECT 7
  640. UNION ALL SELECT 8
  641. UNION ALL SELECT 9
  642. UNION ALL SELECT 10
  643. UNION ALL SELECT 11
  644. UNION ALL SELECT 12
  645. UNION ALL SELECT 13
  646. UNION ALL SELECT 14
  647. UNION ALL SELECT 15
  648. UNION ALL SELECT 16
  649. UNION ALL SELECT 17
  650. UNION ALL SELECT 18
  651. UNION ALL SELECT 19
  652. UNION ALL SELECT 20
  653. UNION ALL SELECT 21
  654. UNION ALL SELECT 22
  655. UNION ALL SELECT 23
  656. ),
  657. order_data AS (
  658. SELECT
  659. o.id,
  660. si.commission_rate,
  661. o.final_price,
  662. ocm.used_time,
  663. o.pay_time,
  664. o.status
  665. FROM life_user_order o
  666. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  667. LEFT JOIN store_info si ON si.id = o.store_id
  668. WHERE o.delete_flag = 0
  669. )
  670. -- 主查询,左连接小时序列和原查询结果
  671. SELECT
  672. concat(h.hour_of_day,":00") AS hour_num,
  673. COALESCE(orders.order_count, 0) AS profit
  674. FROM
  675. hours h
  676. LEFT JOIN (
  677. SELECT
  678. HOUR(CASE WHEN oa.`status` = 1 THEN oa.used_time ELSE oa.pay_time END) AS hour_of_day,
  679. COUNT(*) AS order_count
  680. FROM
  681. order_data oa
  682. WHERE
  683. (
  684. oa.`status` = 2
  685. AND oa.used_time > #{dataTime}
  686. )
  687. OR (
  688. oa.`status` = 1
  689. AND oa.pay_time > #{dataTime}
  690. )
  691. GROUP BY
  692. HOUR(CASE WHEN oa.`status` = 2 THEN oa.used_time ELSE oa.pay_time END)
  693. ) orders ON h.hour_of_day = orders.hour_of_day
  694. ORDER BY
  695. h.hour_of_day;
  696. </select>
  697. <select id="getOrderQuantityWeek" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  698. WITH RECURSIVE date_sequence AS (
  699. SELECT DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) AS hour_num
  700. UNION ALL
  701. SELECT hour_num + INTERVAL 1 DAY
  702. FROM date_sequence
  703. WHERE hour_num &lt; DATE_SUB(#{dataTime}, INTERVAL WEEKDAY(#{dataTime}) DAY) + INTERVAL 6 DAY
  704. ),
  705. order_data AS (
  706. SELECT
  707. o.id,
  708. si.commission_rate,
  709. o.final_price,
  710. ocm.used_time,
  711. o.pay_time,
  712. o.status
  713. FROM life_user_order o
  714. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  715. LEFT JOIN store_info si ON si.id = o.store_id
  716. WHERE o.delete_flag = 0
  717. )
  718. SELECT
  719. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  720. COALESCE(count(o.id), 0) AS profit
  721. FROM
  722. date_sequence ds
  723. LEFT JOIN
  724. order_data o
  725. ON
  726. (o.used_time >= ds.hour_num AND o.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  727. AND o.`status` = 2) or
  728. (o.pay_time >= ds.hour_num AND o.pay_time &lt; ds.hour_num + INTERVAL 1 DAY
  729. AND o.`status` = 1)
  730. GROUP BY
  731. ds.hour_num
  732. ORDER BY
  733. ds.hour_num;
  734. </select>
  735. <select id="getOrderQuantityMonth" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  736. WITH RECURSIVE date_sequence AS (
  737. SELECT DATE_FORMAT(#{dataTime}, '%Y-%m-01') AS hour_num
  738. UNION ALL
  739. SELECT DATE_ADD(hour_num, INTERVAL 1 DAY)
  740. FROM date_sequence
  741. WHERE DATE_ADD(hour_num, INTERVAL 1 DAY) &lt;= LAST_DAY(#{dataTime})
  742. ),
  743. order_data AS (
  744. SELECT
  745. o.id,
  746. si.commission_rate,
  747. o.final_price,
  748. ocm.used_time,
  749. o.pay_time,
  750. o.status
  751. FROM life_user_order o
  752. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  753. LEFT JOIN store_info si ON si.id = o.store_id
  754. WHERE o.delete_flag = 0
  755. )
  756. SELECT
  757. DATE_FORMAT(ds.hour_num, '%c-%d') AS hour_num,
  758. COALESCE(count(o.id), 0) AS profit
  759. FROM
  760. date_sequence ds
  761. LEFT JOIN
  762. order_data o
  763. ON
  764. (o.used_time >= ds.hour_num AND o.used_time &lt; ds.hour_num + INTERVAL 1 DAY
  765. AND o.`status` = 2) or
  766. (o.pay_time >= ds.hour_num AND o.pay_time &lt; ds.hour_num + INTERVAL 1 DAY
  767. AND o.`status` = 1)
  768. GROUP BY
  769. ds.hour_num
  770. ORDER BY
  771. ds.hour_num;
  772. </select>
  773. <select id="getOrderQuantityYear" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  774. WITH months AS (
  775. SELECT
  776. CONCAT(YEAR(#{dataTime}), '-', LPAD(seq, 2, '0')) AS month
  777. FROM (
  778. SELECT 1 AS seq UNION ALL SELECT 2 UNION ALL SELECT 3 UNION ALL
  779. SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL
  780. SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9 UNION ALL
  781. SELECT 10 UNION ALL SELECT 11 UNION ALL SELECT 12
  782. ) seq
  783. ),
  784. order_data AS (
  785. SELECT
  786. o.id,
  787. si.commission_rate,
  788. o.final_price,
  789. ocm.used_time,
  790. o.pay_time,
  791. o.status
  792. FROM life_user_order o
  793. LEFT JOIN order_coupon_middle ocm ON ocm.order_id = o.id
  794. LEFT JOIN store_info si ON si.id = o.store_id
  795. WHERE o.delete_flag = 0
  796. )
  797. SELECT
  798. m.MONTH AS hour_num,
  799. COALESCE(orders.order_count, 0) AS profit
  800. FROM
  801. months m
  802. LEFT JOIN (
  803. SELECT
  804. DATE_FORMAT(CASE WHEN oa.`status` = 1 THEN oa.used_time ELSE oa.pay_time END, '%Y-%m') AS month,
  805. COUNT(*) AS order_count
  806. FROM
  807. order_data oa
  808. WHERE
  809. (
  810. oa.`status` = 2
  811. AND oa.used_time > #{dataTime}
  812. )
  813. OR (
  814. oa.`status` = 1
  815. AND pay_time > #{dataTime}
  816. )
  817. GROUP BY
  818. DATE_FORMAT(CASE WHEN `status` = 2 THEN used_time ELSE pay_time END, '%Y-%m')
  819. ) orders ON m.month = orders.month
  820. ORDER BY
  821. m.month;
  822. </select>
  823. <select id="getSalesVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  824. <!-- 初始化用户变量 -->
  825. SELECT
  826. profit,
  827. store.`store_name`
  828. FROM
  829. (
  830. SELECT
  831. count(id) AS profit,
  832. store_id
  833. FROM
  834. life_user_order
  835. WHERE
  836. ( `status` = 7 AND finish_time >= #{startTime} AND finish_time &lt; #{endTime})
  837. OR ( `status` = 1 AND pay_time >= #{startTime} AND pay_time &lt; #{endTime})
  838. GROUP BY
  839. store_id
  840. LIMIT 10
  841. ) statistic
  842. LEFT JOIN store_info store ON store.id = statistic.store_id
  843. ORDER BY
  844. profit DESC limit 10
  845. </select>
  846. <select id="getStorePlatformProfitDetails" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  847. SELECT
  848. store_id,
  849. store.store_name,
  850. ROUND(SUM(final_price), 2 ) AS operation_revenue,
  851. ROUND(SUM(final_price) - ROUND(SUM(final_price) * (IFNULL(store.commission_rate, 3)/100),2), 2) AS store_profit,
  852. ROUND(SUM(final_price) * (IFNULL(store.commission_rate, 3)/100),2) AS platform_profit
  853. FROM
  854. life_user_order `order`
  855. LEFT JOIN store_info store ON store.id = `order`.store_id
  856. WHERE
  857. `status` = 2
  858. <if test="startTime != null and startTime != ''" >
  859. AND used_time > #{startTime}
  860. </if>
  861. <if test="endTime != null and endTime != ''" >
  862. AND used_time &lt; #{endTime}
  863. </if>
  864. <if test="storeId != null and storeId != ''" >
  865. AND store_id like concat('%',#{storeId},'%')
  866. </if>
  867. <if test="storeName != null and storeName != ''" >
  868. AND store_name like concat('%',#{storeName},'%')
  869. </if>
  870. GROUP BY
  871. store.id
  872. ORDER BY
  873. `order`.created_time DESC
  874. </select>
  875. <select id="getRefundOrderQuantity" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  876. SELECT
  877. COUNT( 1 ) AS `count`
  878. FROM
  879. life_user_order
  880. WHERE
  881. `status` = 5
  882. <if test="dataTime != null and dataTime != ''">
  883. AND refund_time > #{dataTime}
  884. </if>
  885. </select>
  886. <select id="getTotalOrderVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  887. SELECT
  888. COUNT( 1 ) AS `count`
  889. FROM
  890. life_user_order `order`
  891. WHERE
  892. delete_flag = 0
  893. <if test="dataTime != null and dataTime != ''">
  894. AND buy_time > #{dataTime}
  895. </if>
  896. </select>
  897. <select id="getStorePlatformOrderVolume" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  898. with total_coupon as(
  899. select id coupon_id,2 coupon_type,lgbm.group_name coupon_name, SUBSTRING_INDEX(image_id, ',', 1) AS image_id
  900. from life_group_buy_main lgbm where lgbm.delete_flag = 0
  901. union all
  902. select id coupon_id,1 coupon_type,lc.name coupon_name, SUBSTRING_INDEX(image_path, ',', 1) AS image_id
  903. from life_coupon lc where lc.delete_flag = 0
  904. )
  905. SELECT
  906. order_no,
  907. `order`.id as order_id,
  908. `order`.created_time AS order_time,
  909. `order`.finish_time AS finish_time,
  910. `order`.cancel_time AS cancel_time,
  911. `order`.pay_time AS pay_time,
  912. `order`.buy_time AS buy_time_str,
  913. ROUND(`order`.final_price, 2) AS final_price,
  914. CASE
  915. `order`.`status`
  916. WHEN 0 THEN '待支付'
  917. WHEN 1 THEN '已支付/待使用'
  918. WHEN 2 THEN '已核销'
  919. WHEN 3 THEN '已过期'
  920. WHEN 4 THEN '已取消'
  921. WHEN 5 THEN '已退款'
  922. WHEN 6 THEN '退款失败'
  923. WHEN 7 THEN '已完成'
  924. END AS status_name,
  925. simg.img_url,
  926. tc.*,
  927. store.store_name
  928. FROM
  929. life_user_order `order`
  930. left join store_info store on `order`.store_id = store.id
  931. left join order_coupon_middle ocm on ocm.order_id = `order`.id and ocm.delete_flag = 0
  932. inner join total_coupon tc on tc.coupon_id = ocm.coupon_id and tc.coupon_type = `order`.coupon_type
  933. left join store_img simg on simg.id = tc.image_id and simg.delete_flag = 0
  934. <where>
  935. 1 = 1
  936. <if test="orderType != null and orderType != ''">
  937. AND `order`.`status` = #{orderType}
  938. </if>
  939. <if test="startTime != null and startTime != ''">
  940. AND buy_time > #{startTime}
  941. </if>
  942. <if test="orderId != null and orderId != ''">
  943. AND `order`.`order_no` like concat('%',#{orderId},'%')
  944. </if>
  945. <if test="couponType != null and couponType != ''">
  946. AND tc.coupon_type = #{couponType}
  947. </if>
  948. <if test="couponName != null and couponName != ''">
  949. AND tc.coupon_name like concat('%',#{couponName},'%')
  950. </if>
  951. <if test="storeName != null and storeName != ''">
  952. AND store.store_name like concat('%',#{storeName},'%')
  953. </if>
  954. </where>
  955. GROUP by `order`.`id`
  956. ORDER BY `order`.created_time DESC
  957. </select>
  958. <select id="getRefundAmount" resultType="shop.alien.entity.store.vo.ManagementInfoVo">
  959. SELECT
  960. IFNULL(ROUND( SUM( final_price ), 2 ),0) AS profit
  961. FROM
  962. life_user_order `order`
  963. WHERE
  964. `status` = 4
  965. <if test="dataTime != null and dataTime != ''" >
  966. AND `order`.refund_time > #{dataTime}
  967. </if>
  968. </select>
  969. </mapper>