fix(model): enhance user statistics queries with new order and renewal order counts
This commit is contained in:
parent
ff574b3955
commit
d578dca17e
@ -174,12 +174,12 @@ func (m *customOrderModel) QueryTotalOrders(ctx context.Context) (OrdersTotal, e
|
|||||||
|
|
||||||
err := m.QueryNoCacheCtx(ctx, &result, func(conn *gorm.DB, _ interface{}) error {
|
err := m.QueryNoCacheCtx(ctx, &result, func(conn *gorm.DB, _ interface{}) error {
|
||||||
return conn.Model(&Order{}).
|
return conn.Model(&Order{}).
|
||||||
Where("status IN ? AND method != ?", []int64{2, 5}, "balance").
|
|
||||||
Select(`
|
Select(`
|
||||||
SUM(amount) AS amount_total,
|
SUM(amount) AS amount_total,
|
||||||
SUM(CASE WHEN is_new = 1 THEN amount ELSE 0 END) AS new_order_amount,
|
SUM(CASE WHEN is_new = 1 THEN amount ELSE 0 END) AS new_order_amount,
|
||||||
SUM(CASE WHEN is_new = 0 THEN amount ELSE 0 END) AS renewal_order_amount
|
SUM(CASE WHEN is_new = 0 THEN amount ELSE 0 END) AS renewal_order_amount
|
||||||
`).
|
`).
|
||||||
|
Where("status IN ? AND method != ?", []int64{2, 5}, "balance").
|
||||||
Scan(&result).Error
|
Scan(&result).Error
|
||||||
})
|
})
|
||||||
|
|
||||||
@ -267,14 +267,14 @@ func (m *customOrderModel) QueryDailyOrdersList(ctx context.Context, date time.T
|
|||||||
|
|
||||||
return conn.Model(&Order{}).
|
return conn.Model(&Order{}).
|
||||||
Select(`
|
Select(`
|
||||||
DATE(created_at) AS date,
|
DATE_FORMAT(created_at, '%Y-%m-%d') AS date,
|
||||||
SUM(amount) AS amount_total,
|
SUM(amount) AS amount_total,
|
||||||
SUM(CASE WHEN is_new = 1 THEN amount ELSE 0 END) AS new_order_amount,
|
SUM(CASE WHEN is_new = 1 THEN amount ELSE 0 END) AS new_order_amount,
|
||||||
SUM(CASE WHEN is_new = 0 THEN amount ELSE 0 END) AS renewal_order_amount
|
SUM(CASE WHEN is_new = 0 THEN amount ELSE 0 END) AS renewal_order_amount
|
||||||
`).
|
`).
|
||||||
Where("status IN ? AND created_at >= ? AND created_at < ? AND method != ?",
|
Where("status IN ? AND created_at >= ? AND created_at < ? AND method != ?",
|
||||||
[]int64{2, 5}, firstDay, nextDay, "balance").
|
[]int64{2, 5}, firstDay, nextDay, "balance").
|
||||||
Group("DATE(created_at)").
|
Group("DATE_FORMAT(created_at, '%Y-%m-%d')").
|
||||||
Order("date ASC").
|
Order("date ASC").
|
||||||
Scan(v).Error
|
Scan(v).Error
|
||||||
})
|
})
|
||||||
|
|||||||
@ -5,6 +5,7 @@ import (
|
|||||||
"fmt"
|
"fmt"
|
||||||
"time"
|
"time"
|
||||||
|
|
||||||
|
"github.com/perfect-panel/server/internal/model/order"
|
||||||
"github.com/perfect-panel/server/internal/model/subscribe"
|
"github.com/perfect-panel/server/internal/model/subscribe"
|
||||||
|
|
||||||
"github.com/redis/go-redis/v9"
|
"github.com/redis/go-redis/v9"
|
||||||
@ -250,39 +251,74 @@ func (m *customUserModel) FindOneSubscribeDetailsById(ctx context.Context, id in
|
|||||||
// QueryDailyUserStatisticsList Query daily user statistics list for the current month (from 1st to current date)
|
// QueryDailyUserStatisticsList Query daily user statistics list for the current month (from 1st to current date)
|
||||||
func (m *customUserModel) QueryDailyUserStatisticsList(ctx context.Context, date time.Time) ([]UserStatisticsWithDate, error) {
|
func (m *customUserModel) QueryDailyUserStatisticsList(ctx context.Context, date time.Time) ([]UserStatisticsWithDate, error) {
|
||||||
var results []UserStatisticsWithDate
|
var results []UserStatisticsWithDate
|
||||||
|
|
||||||
err := m.QueryNoCacheCtx(ctx, &results, func(conn *gorm.DB, v interface{}) error {
|
err := m.QueryNoCacheCtx(ctx, &results, func(conn *gorm.DB, v interface{}) error {
|
||||||
firstDay := time.Date(date.Year(), date.Month(), 1, 0, 0, 0, 0, date.Location())
|
firstDay := time.Date(date.Year(), date.Month(), 1, 0, 0, 0, 0, date.Location())
|
||||||
|
|
||||||
|
// 子查询:统计每天的新用户订单数量
|
||||||
|
newOrderSub := conn.Model(&order.Order{}).
|
||||||
|
Select("DATE_FORMAT(created_at, '%Y-%m-%d') AS date, COUNT(DISTINCT user_id) AS new_order_users").
|
||||||
|
Where("is_new = 1 AND created_at BETWEEN ? AND ? AND status IN ?", firstDay, date, []int64{2, 5}).
|
||||||
|
Group("DATE_FORMAT(created_at, '%Y-%m-%d')")
|
||||||
|
|
||||||
|
// 子查询:统计每天的续费订单数量
|
||||||
|
renewalOrderSub := conn.Model(&order.Order{}).
|
||||||
|
Select("DATE_FORMAT(created_at, '%Y-%m-%d') AS date, COUNT(DISTINCT user_id) AS renewal_order_users").
|
||||||
|
Where("is_new = 0 AND created_at BETWEEN ? AND ? AND status IN ?", firstDay, date, []int64{2, 5}).
|
||||||
|
Group("DATE_FORMAT(created_at, '%Y-%m-%d')")
|
||||||
|
|
||||||
return conn.Model(&User{}).
|
return conn.Model(&User{}).
|
||||||
Select(
|
Select(`
|
||||||
"DATE(created_at) as date, "+
|
DATE_FORMAT(user.created_at, '%Y-%m-%d') AS date,
|
||||||
"COUNT(*) as register, "+
|
COUNT(*) AS register,
|
||||||
"0 as new_order_users, "+
|
IFNULL(MAX(n.new_order_users), 0) AS new_order_users,
|
||||||
"0 as renewal_order_users",
|
IFNULL(MAX(r.renewal_order_users), 0) AS renewal_order_users
|
||||||
).
|
`).
|
||||||
Where("created_at BETWEEN ? AND ?", firstDay, date).
|
Joins("LEFT JOIN (?) AS n ON DATE_FORMAT(user.created_at, '%Y-%m-%d') = n.date", newOrderSub).
|
||||||
Group("DATE(created_at)").
|
Joins("LEFT JOIN (?) AS r ON DATE_FORMAT(user.created_at, '%Y-%m-%d') = r.date", renewalOrderSub).
|
||||||
|
Where("user.created_at BETWEEN ? AND ?", firstDay, date).
|
||||||
|
Group("DATE_FORMAT(user.created_at, '%Y-%m-%d')").
|
||||||
Order("date ASC").
|
Order("date ASC").
|
||||||
Scan(v).Error
|
Scan(v).Error
|
||||||
})
|
})
|
||||||
|
|
||||||
return results, err
|
return results, err
|
||||||
}
|
}
|
||||||
|
|
||||||
// QueryMonthlyUserStatisticsList Query monthly user statistics list for the past 6 months
|
// QueryMonthlyUserStatisticsList Query monthly user statistics list for the past 6 months
|
||||||
func (m *customUserModel) QueryMonthlyUserStatisticsList(ctx context.Context, date time.Time) ([]UserStatisticsWithDate, error) {
|
func (m *customUserModel) QueryMonthlyUserStatisticsList(ctx context.Context, date time.Time) ([]UserStatisticsWithDate, error) {
|
||||||
var results []UserStatisticsWithDate
|
var results []UserStatisticsWithDate
|
||||||
|
|
||||||
err := m.QueryNoCacheCtx(ctx, &results, func(conn *gorm.DB, v interface{}) error {
|
err := m.QueryNoCacheCtx(ctx, &results, func(conn *gorm.DB, v interface{}) error {
|
||||||
|
// 获取 6 个月前的日期
|
||||||
sixMonthsAgo := date.AddDate(0, -5, 0)
|
sixMonthsAgo := date.AddDate(0, -5, 0)
|
||||||
|
|
||||||
|
// 子查询:每月新订单用户数量
|
||||||
|
newOrderSub := conn.Model(&order.Order{}).
|
||||||
|
Select("DATE_FORMAT(created_at, '%Y-%m') AS date, COUNT(DISTINCT user_id) AS new_order_users").
|
||||||
|
Where("is_new = 1 AND created_at >= ? AND status IN ?", sixMonthsAgo, []int64{2, 5}).
|
||||||
|
Group("DATE_FORMAT(created_at, '%Y-%m')")
|
||||||
|
|
||||||
|
// 子查询:每月续费订单用户数量
|
||||||
|
renewalOrderSub := conn.Model(&order.Order{}).
|
||||||
|
Select("DATE_FORMAT(created_at, '%Y-%m') AS date, COUNT(DISTINCT user_id) AS renewal_order_users").
|
||||||
|
Where("is_new = 0 AND created_at >= ? AND status IN ?", sixMonthsAgo, []int64{2, 5}).
|
||||||
|
Group("DATE_FORMAT(created_at, '%Y-%m')")
|
||||||
|
|
||||||
return conn.Model(&User{}).
|
return conn.Model(&User{}).
|
||||||
Select(
|
Select(`
|
||||||
"DATE_FORMAT(created_at, '%Y-%m') as date, "+
|
DATE_FORMAT(user.created_at, '%Y-%m') AS date,
|
||||||
"COUNT(*) as register, "+
|
COUNT(*) AS register,
|
||||||
"0 as new_order_users, "+
|
IFNULL(MAX(n.new_order_users), 0) AS new_order_users,
|
||||||
"0 as renewal_order_users",
|
IFNULL(MAX(r.renewal_order_users), 0) AS renewal_order_users
|
||||||
).
|
`).
|
||||||
Where("created_at >= ?", sixMonthsAgo).
|
Joins("LEFT JOIN (?) AS n ON DATE_FORMAT(user.created_at, '%Y-%m') = n.date", newOrderSub).
|
||||||
Group("DATE_FORMAT(created_at, '%Y-%m')").
|
Joins("LEFT JOIN (?) AS r ON DATE_FORMAT(user.created_at, '%Y-%m') = r.date", renewalOrderSub).
|
||||||
|
Where("user.created_at >= ?", sixMonthsAgo).
|
||||||
|
Group("DATE_FORMAT(user.created_at, '%Y-%m')").
|
||||||
Order("date ASC").
|
Order("date ASC").
|
||||||
Scan(v).Error
|
Scan(v).Error
|
||||||
})
|
})
|
||||||
|
|
||||||
return results, err
|
return results, err
|
||||||
}
|
}
|
||||||
|
|||||||
Loading…
x
Reference in New Issue
Block a user