From e4e4ceb7c1075d0cb4cc7bf05a402ad46ea302c6 Mon Sep 17 00:00:00 2001 From: cll <931958862@qq.com> Date: Sat, 23 Aug 2025 11:48:45 +0800 Subject: [PATCH] =?UTF-8?q?fix:=E4=BC=98=E5=8C=96=E9=94=80=E5=94=AE?= =?UTF-8?q?=E7=BB=9F=E8=AE=A1=E6=8E=A5=E5=8F=A3?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- src/entity/order_sale.entity.ts | 43 ++++ src/service/order.service.ts | 385 ++++++++++---------------------- 2 files changed, 167 insertions(+), 261 deletions(-) diff --git a/src/entity/order_sale.entity.ts b/src/entity/order_sale.entity.ts index d8947cf..e7958ed 100644 --- a/src/entity/order_sale.entity.ts +++ b/src/entity/order_sale.entity.ts @@ -1,6 +1,8 @@ import { ApiProperty } from '@midwayjs/swagger'; import { Exclude, Expose } from 'class-transformer'; import { + BeforeInsert, + BeforeUpdate, Column, CreateDateColumn, Entity, @@ -56,6 +58,26 @@ export class OrderSale { @Expose() isPackage: boolean; + @ApiProperty() + @Column({ default: false }) + @Expose() + isYoone: boolean; + + @ApiProperty() + @Column({ default: false }) + @Expose() + isZex: boolean; + + @ApiProperty({ nullable: true }) + @Column({ type: 'int', nullable: true }) + @Expose() + size: number | null; + + @ApiProperty() + @Column({ default: false }) + @Expose() + isYooneNew: boolean; + @ApiProperty({ example: '2022-12-12 11:11:11', description: '创建时间', @@ -71,4 +93,25 @@ export class OrderSale { @UpdateDateColumn() @Expose() updatedAt?: Date; + + // === 自动计算逻辑 === + @BeforeInsert() + @BeforeUpdate() + setFlags() { + if (!this.name) return; + const lower = this.name.toLowerCase(); + this.isYoone = lower.includes('yoone'); + this.isZex = lower.includes('zex'); + this.isYooneNew = this.isYoone && lower.includes('new'); + let size: number | null = null; + const sizes = [3, 6, 9, 12, 15, 18]; + for (const s of sizes) { + if (lower.includes(s.toString())) { + size = s; + break; + } + } + this.size = size; + } + } diff --git a/src/service/order.service.ts b/src/service/order.service.ts index 34bfc1d..90b99db 100644 --- a/src/service/order.service.ts +++ b/src/service/order.service.ts @@ -740,296 +740,159 @@ export class OrderService { async getOrderSales({ siteId, startDate, endDate, current, pageSize, name }: QueryOrderSalesDTO) { const nameKeywords = name ? name.split(' ').filter(Boolean) : []; + const offset = (current - 1) * pageSize; - const parameters: any[] = [startDate, endDate]; - - // 主查询:带分页 - let sqlQuery = ` - WITH product_purchase_counts AS ( - SELECT - o.customer_email, - os.productId, - COUNT(DISTINCT o.id) AS order_count - FROM \`order\` o - JOIN order_sale os ON o.id = os.orderId - WHERE o.status IN ('completed', 'processing') - GROUP BY o.customer_email, os.productId - ) - SELECT - os.productId AS productId, - os.name AS name, - SUM(os.quantity) AS totalQuantity, - COUNT(DISTINCT os.orderId) AS totalOrders, - c.name AS categoryName, - COUNT(DISTINCT CASE WHEN pc.order_count = 1 THEN o.id END) AS firstOrderCount, - SUM(CASE WHEN pc.order_count = 1 THEN os.quantity ELSE 0 END) AS firstOrderYOONEBoxCount, - COUNT(DISTINCT CASE WHEN pc.order_count = 2 THEN o.id END) AS secondOrderCount, - SUM(CASE WHEN pc.order_count = 2 THEN os.quantity ELSE 0 END) AS secondOrderYOONEBoxCount, - COUNT(DISTINCT CASE WHEN pc.order_count = 3 THEN o.id END) AS thirdOrderCount, - SUM(CASE WHEN pc.order_count = 3 THEN os.quantity ELSE 0 END) AS thirdOrderYOONEBoxCount, - COUNT(DISTINCT CASE WHEN pc.order_count > 3 THEN o.id END) AS moreThirdOrderCount, - SUM(CASE WHEN pc.order_count > 3 THEN os.quantity ELSE 0 END) AS moreThirdOrderYOONEBoxCount - FROM order_sale os - INNER JOIN \`order\` o ON o.id = os.orderId - INNER JOIN product p ON os.productId = p.id - INNER JOIN category c ON p.categoryId = c.id - INNER JOIN product_purchase_counts pc ON pc.customer_email = o.customer_email AND pc.productId = os.productId - WHERE o.date_paid BETWEEN ? AND ? - AND o.status IN ('completed', 'processing') - `; - - if (siteId) { - sqlQuery += ' AND os.siteId = ?'; - parameters.push(siteId); - } - - if (nameKeywords.length > 0) { - sqlQuery += ' AND (' + nameKeywords.map(() => 'os.name LIKE ?').join(' OR ') + ')'; - parameters.push(...nameKeywords.map(word => `%${word}%`)); - } - - sqlQuery += ` - GROUP BY os.productId, os.name, c.name - ORDER BY totalQuantity DESC - LIMIT ? OFFSET ? - `; - - parameters.push(pageSize, (current - 1) * pageSize); - const items = await this.orderSaleModel.query(sqlQuery, parameters); - - // 总条数 + // ------------------------- + // 1. 查询总条数 + // ------------------------- const countParams: any[] = [startDate, endDate]; - let totalCountQuery = ` + let countSql = ` SELECT COUNT(DISTINCT os.productId) AS totalCount FROM order_sale os INNER JOIN \`order\` o ON o.id = os.orderId WHERE o.date_paid BETWEEN ? AND ? - AND o.status IN ('completed', 'processing') + AND o.status IN ('completed','processing') `; if (siteId) { - totalCountQuery += ' AND os.siteId = ?'; + countSql += ' AND os.siteId = ?'; countParams.push(siteId); } if (nameKeywords.length > 0) { - totalCountQuery += ' AND (' + nameKeywords.map(() => 'os.name LIKE ?').join(' OR ') + ')'; - countParams.push(...nameKeywords.map(word => `%${word}%`)); + countSql += ' AND (' + nameKeywords.map(() => 'os.name LIKE ?').join(' AND ') + ')'; + countParams.push(...nameKeywords.map(w => `%${w}%`)); + } + const [countResult] = await this.orderSaleModel.query(countSql, countParams); + const totalCount = Number(countResult?.totalCount || 0); + + // ------------------------- + // 2. 分页查询 product 基础信息 + // ------------------------- + const itemParams: any[] = [startDate, endDate]; + let nameCondition = ''; + if (nameKeywords.length > 0) { + nameCondition = ' AND (' + nameKeywords.map(() => 'os.name LIKE ?').join(' AND ') + ')'; + itemParams.push(...nameKeywords.map(w => `%${w}%`)); } - const totalCountResult = await this.orderSaleModel.query(totalCountQuery, countParams); - - // 一次查询获取所有 yoone box 数量 - const totalQuantityParams: any[] = [startDate, endDate]; - let totalQuantityQuery = ` - SELECT - SUM(os.quantity) AS totalQuantity, - SUM(CASE WHEN os.name LIKE '%yoone%' AND os.name LIKE '%3%' THEN os.quantity ELSE 0 END) AS yoone3Quantity, - SUM(CASE WHEN os.name LIKE '%yoone%' AND os.name LIKE '%6%' THEN os.quantity ELSE 0 END) AS yoone6Quantity, - SUM(CASE WHEN os.name LIKE '%yoone%' AND os.name LIKE '%9%' THEN os.quantity ELSE 0 END) AS yoone9Quantity, - SUM(CASE WHEN os.name LIKE '%yoone%' AND os.name LIKE '%12%' THEN os.quantity ELSE 0 END) AS yoone12Quantity, - SUM(CASE WHEN os.name LIKE '%yoone%' AND os.name LIKE '%12%' AND os.name LIKE '%NEW%' THEN os.quantity ELSE 0 END) AS yoone12QuantityNew, - SUM(CASE WHEN os.name LIKE '%yoone%' AND os.name LIKE '%15%' THEN os.quantity ELSE 0 END) AS yoone15Quantity, - SUM(CASE WHEN os.name LIKE '%yoone%' AND os.name LIKE '%18%' THEN os.quantity ELSE 0 END) AS yoone18Quantity, - SUM(CASE WHEN os.name LIKE '%zex%' THEN os.quantity ELSE 0 END) AS zexQuantity + let itemSql = ` + SELECT os.productId, os.name, SUM(os.quantity) AS totalQuantity, COUNT(DISTINCT os.orderId) AS totalOrders FROM order_sale os INNER JOIN \`order\` o ON o.id = os.orderId WHERE o.date_paid BETWEEN ? AND ? - AND o.status IN ('completed', 'processing') + AND o.status IN ('completed','processing') `; if (siteId) { - totalQuantityQuery += ' AND os.siteId = ?'; - totalQuantityParams.push(siteId); + itemSql += ' AND os.siteId = ?'; + itemParams.push(siteId); } - if (nameKeywords.length > 0) { - totalQuantityQuery += ' AND (' + nameKeywords.map(() => 'os.name LIKE ?').join(' OR ') + ')'; - totalQuantityParams.push(...nameKeywords.map(word => `%${word}%`)); + itemSql += nameCondition; + itemSql += ` + GROUP BY os.productId, os.name + ORDER BY totalQuantity DESC + LIMIT ? OFFSET ? + `; + itemParams.push(pageSize, offset); + const items = await this.orderSaleModel.query(itemSql, itemParams); + + // ------------------------- + // 3. 批量统计当前页 product 历史复购 + // ------------------------- + if (items.length > 0) { + const productIds = items.map(i => i.productId); + const pcParams: any[] = [...productIds, startDate, endDate]; + if (siteId) pcParams.push(siteId); + + const pcSql = ` + SELECT + os.productId, + SUM(CASE WHEN t.purchaseIndex = 1 THEN os.quantity ELSE 0 END) AS firstOrderYOONEBoxCount, + COUNT(CASE WHEN t.purchaseIndex = 1 THEN 1 END) AS firstOrderCount, + SUM(CASE WHEN t.purchaseIndex = 2 THEN os.quantity ELSE 0 END) AS secondOrderYOONEBoxCount, + COUNT(CASE WHEN t.purchaseIndex = 2 THEN 1 END) AS secondOrderCount, + SUM(CASE WHEN t.purchaseIndex = 3 THEN os.quantity ELSE 0 END) AS thirdOrderYOONEBoxCount, + COUNT(CASE WHEN t.purchaseIndex = 3 THEN 1 END) AS thirdOrderCount, + SUM(CASE WHEN t.purchaseIndex > 3 THEN os.quantity ELSE 0 END) AS moreThirdOrderYOONEBoxCount, + COUNT(CASE WHEN t.purchaseIndex > 3 THEN 1 END) AS moreThirdOrderCount + FROM order_sale os + INNER JOIN ( + SELECT o2.id AS orderId, + @idx := IF(@prev_email = o2.customer_email, @idx + 1, 1) AS purchaseIndex, + @prev_email := o2.customer_email + FROM \`order\` o2 + CROSS JOIN (SELECT @idx := 0, @prev_email := '') vars + WHERE o2.status IN ('completed','processing') + ORDER BY o2.customer_email, o2.date_paid + ) t ON t.orderId = os.orderId + WHERE os.productId IN (${productIds.map(() => '?').join(',')}) + AND os.orderId IN ( + SELECT id FROM \`order\` + WHERE date_paid BETWEEN ? AND ? + ${siteId ? 'AND siteId = ?' : ''} + ) + GROUP BY os.productId + `; + + const pcResults = await this.orderSaleModel.query(pcSql, pcParams); + + const pcMap = new Map(); + pcResults.forEach(r => pcMap.set(r.productId, r)); + items.forEach(i => { + const r = pcMap.get(i.productId) || {}; + i.firstOrderYOONEBoxCount = Number(r.firstOrderYOONEBoxCount || 0); + i.firstOrderCount = Number(r.firstOrderCount || 0); + i.secondOrderYOONEBoxCount = Number(r.secondOrderYOONEBoxCount || 0); + i.secondOrderCount = Number(r.secondOrderCount || 0); + i.thirdOrderYOONEBoxCount = Number(r.thirdOrderYOONEBoxCount || 0); + i.thirdOrderCount = Number(r.thirdOrderCount || 0); + i.moreThirdOrderYOONEBoxCount = Number(r.moreThirdOrderYOONEBoxCount || 0); + i.moreThirdOrderCount = Number(r.moreThirdOrderCount || 0); + }); } - const [totalQuantityResult] = await this.orderSaleModel.query(totalQuantityQuery, totalQuantityParams); + // ------------------------- + // 4. 总量统计(时间段 + siteId) + // ------------------------- + const totalParams: any[] = [startDate, endDate]; + let totalSql = ` + SELECT + SUM(os.quantity) AS totalQuantity, + SUM(CASE WHEN os.isYoone = 1 AND os.size = 3 THEN os.quantity ELSE 0 END) AS yoone3Quantity, + SUM(CASE WHEN os.isYoone = 1 AND os.size = 6 THEN os.quantity ELSE 0 END) AS yoone6Quantity, + SUM(CASE WHEN os.isYoone = 1 AND os.size = 9 THEN os.quantity ELSE 0 END) AS yoone9Quantity, + SUM(CASE WHEN os.isYoone = 1 AND os.size = 12 THEN os.quantity ELSE 0 END) AS yoone12Quantity, + SUM(CASE WHEN os.isYooneNew = 1 AND os.size = 12 THEN os.quantity ELSE 0 END) AS yoone12QuantityNew, + SUM(CASE WHEN os.isYoone = 1 AND os.size = 15 THEN os.quantity ELSE 0 END) AS yoone15Quantity, + SUM(CASE WHEN os.isYoone = 1 AND os.size = 18 THEN os.quantity ELSE 0 END) AS yoone18Quantity, + SUM(CASE WHEN os.isZex = 1 THEN os.quantity ELSE 0 END) AS zexQuantity + FROM order_sale os + INNER JOIN \`order\` o ON o.id = os.orderId + WHERE o.date_paid BETWEEN ? AND ? + AND o.status IN ('completed','processing') + `; + if (siteId) { + totalSql += ' AND os.siteId = ?'; + totalParams.push(siteId); + } + const [totalResult] = await this.orderSaleModel.query(totalSql, totalParams); return { items, - total: totalCountResult[0]?.totalCount || 0, - totalQuantity: Number(totalQuantityResult.totalQuantity || 0), - yoone3Quantity: Number(totalQuantityResult.yoone3Quantity || 0), - yoone6Quantity: Number(totalQuantityResult.yoone6Quantity || 0), - yoone9Quantity: Number(totalQuantityResult.yoone9Quantity || 0), - yoone12Quantity: Number(totalQuantityResult.yoone12Quantity || 0), - yoone12QuantityNew: Number(totalQuantityResult.yoone12QuantityNew || 0), - yoone15Quantity: Number(totalQuantityResult.yoone15Quantity || 0), - yoone18Quantity: Number(totalQuantityResult.yoone18Quantity || 0), - zexQuantity: Number(totalQuantityResult.zexQuantity || 0), + total: totalCount, // ✅ 总条数 + totalQuantity: Number(totalResult.totalQuantity || 0), + yoone3Quantity: Number(totalResult.yoone3Quantity || 0), + yoone6Quantity: Number(totalResult.yoone6Quantity || 0), + yoone9Quantity: Number(totalResult.yoone9Quantity || 0), + yoone12Quantity: Number(totalResult.yoone12Quantity || 0), + yoone12QuantityNew: Number(totalResult.yoone12QuantityNew || 0), + yoone15Quantity: Number(totalResult.yoone15Quantity || 0), + yoone18Quantity: Number(totalResult.yoone18Quantity || 0), + zexQuantity: Number(totalResult.zexQuantity || 0), current, pageSize, }; } - // async getOrderSales({ - // siteId, - // startDate, - // endDate, - // current, - // pageSize, - // name, - // }: QueryOrderSalesDTO) { - // const nameKeywords = name ? name.split(' ').filter(Boolean) : []; - // // 分页查询 - // let sqlQuery = ` - // WITH product_purchase_counts AS ( - // SELECT o.customer_email,os.productId, os.name, COUNT(DISTINCT o.id,os.productId) AS order_count - // FROM \`order\` o - // JOIN order_sale os ON o.id = os.orderId - // WHERE o.status IN ('completed', 'processing') - // GROUP BY o.customer_email, os.productId, os.name - // ) - // SELECT - // os.productId AS productId, - // os.name AS name, - // SUM(os.quantity) AS totalQuantity, - // COUNT(distinct os.orderId) AS totalOrders, - // c.name AS categoryName, - // COUNT(DISTINCT CASE WHEN pc.order_count = 1 THEN o.id END) AS firstOrderCount, - // SUM(CASE WHEN pc.order_count = 1 THEN os.quantity ELSE 0 END) AS firstOrderYOONEBoxCount, - // COUNT(DISTINCT CASE WHEN pc.order_count = 2 THEN o.id END) AS secondOrderCount, - // SUM(CASE WHEN pc.order_count = 2 THEN os.quantity ELSE 0 END) AS secondOrderYOONEBoxCount, - // COUNT(DISTINCT CASE WHEN pc.order_count = 3 THEN o.id END) AS thirdOrderCount, - // SUM(CASE WHEN pc.order_count = 3 THEN os.quantity ELSE 0 END) AS thirdOrderYOONEBoxCount, - // COUNT(DISTINCT CASE WHEN pc.order_count > 3 THEN o.id END) AS moreThirdOrderCount, - // SUM(CASE WHEN pc.order_count > 3 THEN os.quantity ELSE 0 END) AS moreThirdOrderYOONEBoxCount - // FROM order_sale os - // INNER JOIN \`order\` o ON o.id = os.orderId - // INNER JOIN product p ON os.productId = p.id - // INNER JOIN category c ON p.categoryId = c.id - // INNER JOIN product_purchase_counts pc ON pc.customer_email = o.customer_email AND pc.productId = os.productId - // WHERE o.date_paid BETWEEN ? AND ? - // AND o.status IN ('processing', 'completed') - // `; - // const parameters: any[] = [startDate, endDate]; - // if (siteId) { - // sqlQuery += ' AND os.siteId = ?'; - // parameters.push(siteId); - // } - // if (nameKeywords.length > 0) { - // sqlQuery += - // ' AND ' + nameKeywords.map(() => `os.name LIKE ?`).join(' AND '); - // parameters.push(...nameKeywords.map(word => `%${word}%`)); - // } - // sqlQuery += ` - // GROUP BY os.productId, os.name, c.name - // ORDER BY totalQuantity DESC - // `; - // sqlQuery += ' LIMIT ? OFFSET ?'; - // parameters.push(pageSize, (current - 1) * pageSize); - - // // 执行查询并传递参数 - // const items = await this.orderSaleModel.query(sqlQuery, parameters); - - // let totalCountQuery = ` - // SELECT COUNT(DISTINCT os.productId) AS totalCount - // FROM order_sale os - // INNER JOIN \`order\` o ON o.id = os.orderId - // INNER JOIN product p ON os.productId = p.id - // INNER JOIN category c ON p.categoryId = c.id - // WHERE o.date_created BETWEEN ? AND ? - // AND o.status IN ('processing', 'completed') - // `; - // const totalCountParameters: any[] = [startDate, endDate]; - // if (siteId) { - // totalCountQuery += ' AND os.siteId = ?'; - // totalCountParameters.push(siteId); - // } - // if (nameKeywords.length > 0) { - // totalCountQuery += - // ' AND ' + nameKeywords.map(() => `os.name LIKE ?`).join(' AND '); - // totalCountParameters.push(...nameKeywords.map(word => `%${word}%`)); - // } - - // const totalCountResult = await this.orderSaleModel.query( - // totalCountQuery, - // totalCountParameters - // ); - - // let totalQuantityQuery = ` - // SELECT SUM(os.quantity) AS totalQuantity - // FROM order_sale os - // INNER JOIN \`order\` o ON o.id = os.orderId - // INNER JOIN product p ON os.productId = p.id - // INNER JOIN category c ON p.categoryId = c.id - // WHERE o.date_created BETWEEN ? AND ? - // AND o.status IN ('processing', 'completed') - // `; - - // const totalQuantityParameters: any[] = [startDate, endDate]; - // if (siteId) { - // totalQuantityQuery += ' AND os.siteId = ?'; - // totalQuantityParameters.push(siteId); - // } - // const yoone3QuantityQuery = - // totalQuantityQuery + 'AND os.name LIKE "%yoone%" AND os.name LIKE "%3%"'; - // const yoone6QuantityQuery = - // totalQuantityQuery + 'AND os.name LIKE "%yoone%" AND os.name LIKE "%6%"'; - // const yoone9QuantityQuery = - // totalQuantityQuery + 'AND os.name LIKE "%yoone%" AND os.name LIKE "%9%"'; - // const yoone12QuantityQuery = - // totalQuantityQuery + 'AND os.name LIKE "%yoone%" AND os.name LIKE "%12%"'; - // const yoone15QuantityQuery = - // totalQuantityQuery + 'AND os.name LIKE "%yoone%" AND os.name LIKE "%15%"'; - // const yooneParameters = [...totalQuantityParameters]; - // if (nameKeywords.length > 0) { - // totalQuantityQuery += - // ' AND ' + nameKeywords.map(() => `os.name LIKE ?`).join(' AND '); - // totalQuantityParameters.push(...nameKeywords.map(word => `%${word}%`)); - // } - - // const totalQuantityResult = await this.orderSaleModel.query( - // totalQuantityQuery, - // totalQuantityParameters - // ); - // const yoone3QuantityResult = await this.orderSaleModel.query( - // yoone3QuantityQuery, - // yooneParameters - // ); - // const yoone6QuantityResult = await this.orderSaleModel.query( - // yoone6QuantityQuery, - // yooneParameters - // ); - // const yoone9QuantityResult = await this.orderSaleModel.query( - // yoone9QuantityQuery, - // yooneParameters - // ); - // const yoone12QuantityResult = await this.orderSaleModel.query( - // yoone12QuantityQuery, - // yooneParameters - // ); - // const yoone15QuantityResult = await this.orderSaleModel.query( - // yoone15QuantityQuery, - // yooneParameters - // ); - - // return { - // items, - // total: totalCountResult[0]?.totalCount, - // totalQuantity: Number( - // totalQuantityResult.reduce((sum, row) => sum + row.totalQuantity, 0) - // ), - // yoone3Quantity: Number( - // yoone3QuantityResult.reduce((sum, row) => sum + row.totalQuantity, 0) - // ), - // yoone6Quantity: Number( - // yoone6QuantityResult.reduce((sum, row) => sum + row.totalQuantity, 0) - // ), - // yoone9Quantity: Number( - // yoone9QuantityResult.reduce((sum, row) => sum + row.totalQuantity, 0) - // ), - // yoone12Quantity: Number( - // yoone12QuantityResult.reduce((sum, row) => sum + row.totalQuantity, 0) - // ), - // yoone15Quantity: Number( - // yoone15QuantityResult.reduce((sum, row) => sum + row.totalQuantity, 0) - // ), - // current, - // pageSize, - // }; - // } + async getOrderItems({ siteId, startDate,