package repository import ( "context" "time" "apskel-pos-be/internal/entities" "github.com/google/uuid" "gorm.io/gorm" ) type AnalyticsRepository interface { GetPaymentMethodAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time) ([]*entities.PaymentMethodAnalytics, error) GetSalesAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time, groupBy string) ([]*entities.SalesAnalytics, error) GetProductAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time, limit int) ([]*entities.ProductAnalytics, error) GetProductAnalyticsPerCategory(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time) ([]*entities.ProductAnalyticsPerCategory, error) GetDashboardOverview(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time) (*entities.DashboardOverview, error) GetProfitLossAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time, groupBy string) (*entities.ProfitLossAnalytics, error) } type AnalyticsRepositoryImpl struct { db *gorm.DB } func NewAnalyticsRepositoryImpl(db *gorm.DB) *AnalyticsRepositoryImpl { return &AnalyticsRepositoryImpl{ db: db, } } func (r *AnalyticsRepositoryImpl) GetPaymentMethodAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time) ([]*entities.PaymentMethodAnalytics, error) { var results []*entities.PaymentMethodAnalytics query := r.db.WithContext(ctx). Table("payments p"). Select(` pm.id as payment_method_id, pm.name as payment_method_name, pm.type as payment_method_type, COALESCE(SUM(p.amount), 0) as total_amount, COUNT(DISTINCT p.order_id) as order_count, COUNT(p.id) as payment_count `). Joins("JOIN payment_methods pm ON p.payment_method_id = pm.id"). Joins("JOIN orders o ON p.order_id = o.id"). Where("o.organization_id = ?", organizationID). Where("o.is_void = ?", false). Where("o.is_refund = ?", false). Where("p.status = ?", entities.PaymentTransactionStatusCompleted). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo) if outletID != nil { query = query.Where("o.outlet_id = ?", *outletID) } err := query. Group("pm.id, pm.name, pm.type"). Order("total_amount DESC"). Scan(&results).Error return results, err } func (r *AnalyticsRepositoryImpl) GetSalesAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time, groupBy string) ([]*entities.SalesAnalytics, error) { var results []*entities.SalesAnalytics var dateFormat string switch groupBy { case "hour": dateFormat = "DATE_TRUNC('hour', o.created_at)" case "week": dateFormat = "DATE_TRUNC('week', o.created_at)" case "month": dateFormat = "DATE_TRUNC('month', o.created_at)" default: dateFormat = "DATE(o.created_at)" } query := r.db.WithContext(ctx). Table("orders o"). Select(` `+dateFormat+` as date, COALESCE(SUM(o.total_amount), 0) as sales, COUNT(o.id) as orders, COALESCE(SUM(CASE WHEN oi.status != 'cancelled' AND oi.is_fully_refunded = false THEN oi.quantity - COALESCE(oi.refund_quantity, 0) ELSE 0 END), 0) as items, COALESCE(SUM(o.tax_amount), 0) as tax, COALESCE(SUM(o.discount_amount), 0) as discount, COALESCE(SUM(o.total_amount - o.tax_amount - o.discount_amount), 0) as net_sales `). Joins("LEFT JOIN order_items oi ON o.id = oi.order_id"). Where("o.organization_id = ?", organizationID). Where("o.is_void = ?", false). Where("o.is_refund = ?", false). Where("o.payment_status = ?", entities.PaymentStatusCompleted). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo) if outletID != nil { query = query.Where("o.outlet_id = ?", *outletID) } err := query. Group("date"). Order("date ASC"). Scan(&results).Error return results, err } func (r *AnalyticsRepositoryImpl) GetProductAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time, limit int) ([]*entities.ProductAnalytics, error) { var results []*entities.ProductAnalytics query := r.db.WithContext(ctx). Table("order_items oi"). Select(` p.id as product_id, p.name as product_name, c.id as category_id, c.name as category_name, c.order as category_order, COALESCE(SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.quantity - COALESCE(oi.refund_quantity, 0) ELSE 0 END), 0) as quantity_sold, COALESCE(SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.total_price - COALESCE(oi.refund_amount, 0) ELSE 0 END), 0) as revenue, CASE WHEN SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.quantity - COALESCE(oi.refund_quantity, 0) ELSE 0 END) > 0 THEN COALESCE(SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.total_price - COALESCE(oi.refund_amount, 0) ELSE 0 END), 0) / SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.quantity - COALESCE(oi.refund_quantity, 0) ELSE 0 END) ELSE 0 END as average_price, COUNT(DISTINCT oi.order_id) as order_count `). Joins("JOIN products p ON oi.product_id = p.id"). Joins("JOIN categories c ON p.category_id = c.id"). Joins("JOIN orders o ON oi.order_id = o.id"). Where("o.organization_id = ?", organizationID). Where("o.is_void = ?", false). Where("o.is_refund = ?", false). Where("o.payment_status = ?", entities.PaymentStatusCompleted). Where("oi.status != ?", entities.OrderItemStatusCancelled). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo) if outletID != nil { query = query.Where("o.outlet_id = ?", *outletID) } err := query. Group("p.id, p.name, c.id, c.name"). Order("revenue DESC"). Limit(limit). Scan(&results).Error return results, err } func (r *AnalyticsRepositoryImpl) GetProductAnalyticsPerCategory(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time) ([]*entities.ProductAnalyticsPerCategory, error) { var results []*entities.ProductAnalyticsPerCategory query := r.db.WithContext(ctx). Table("order_items oi"). Select(` c.id as category_id, c.name as category_name, COALESCE(SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.total_price - COALESCE(oi.refund_amount, 0) ELSE 0 END), 0) as total_revenue, COALESCE(SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.quantity - COALESCE(oi.refund_quantity, 0) ELSE 0 END), 0) as total_quantity, COUNT(DISTINCT p.id) as product_count, COUNT(DISTINCT oi.order_id) as order_count `). Joins("JOIN products p ON oi.product_id = p.id"). Joins("JOIN categories c ON p.category_id = c.id"). Joins("JOIN orders o ON oi.order_id = o.id"). Where("o.organization_id = ?", organizationID). Where("o.is_void = ?", false). Where("o.is_refund = ?", false). Where("o.payment_status = ?", entities.PaymentStatusCompleted). Where("oi.status != ?", entities.OrderItemStatusCancelled). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo) if outletID != nil { query = query.Where("o.outlet_id = ?", *outletID) } err := query. Group("c.id, c.name"). Order("c.name ASC"). Scan(&results).Error return results, err } func (r *AnalyticsRepositoryImpl) GetDashboardOverview(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time) (*entities.DashboardOverview, error) { var result entities.DashboardOverview query := r.db.WithContext(ctx). Table("orders o"). Select(` COALESCE(SUM(CASE WHEN o.is_void = false THEN o.total_amount ELSE 0 END), 0) as total_sales, COUNT(CASE WHEN o.is_void = false THEN o.id END) as total_orders, CASE WHEN COUNT(CASE WHEN o.is_void = false THEN o.id END) > 0 THEN COALESCE(SUM(CASE WHEN o.is_void = false THEN o.total_amount ELSE 0 END), 0) / COUNT(CASE WHEN o.is_void = false THEN o.id END) ELSE 0 END as average_order_value, COUNT(DISTINCT o.customer_id) as total_customers, COUNT(CASE WHEN o.is_void = true THEN o.id END) as voided_orders, COUNT(CASE WHEN o.is_refund = true THEN o.id END) as refunded_orders `). Where("o.organization_id = ?", organizationID). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo) if outletID != nil { query = query.Where("o.outlet_id = ?", *outletID) } err := query.Scan(&result).Error if err != nil { return nil, err } return &result, nil } func (r *AnalyticsRepositoryImpl) GetProfitLossAnalytics(ctx context.Context, organizationID uuid.UUID, outletID *uuid.UUID, dateFrom, dateTo time.Time, groupBy string) (*entities.ProfitLossAnalytics, error) { // Summary query var summary entities.ProfitLossSummary summaryQuery := r.db.WithContext(ctx). Table("orders o"). Select(` COALESCE(SUM(o.total_amount), 0) as total_revenue, COALESCE(SUM(o.total_cost), 0) as total_cost, COALESCE(SUM(o.total_amount - o.total_cost), 0) as gross_profit, CASE WHEN SUM(o.total_amount) > 0 THEN (SUM(o.total_amount - o.total_cost) / SUM(o.total_amount)) * 100 ELSE 0 END as gross_profit_margin, COALESCE(SUM(o.tax_amount), 0) as total_tax, COALESCE(SUM(o.discount_amount), 0) as total_discount, COALESCE(SUM(o.total_amount - o.total_cost - o.discount_amount), 0) as net_profit, CASE WHEN SUM(o.total_amount) > 0 THEN (SUM(o.total_amount - o.total_cost - o.discount_amount) / SUM(o.total_amount)) * 100 ELSE 0 END as net_profit_margin, COUNT(o.id) as total_orders, CASE WHEN COUNT(o.id) > 0 THEN SUM(o.total_amount - o.total_cost - o.discount_amount) / COUNT(o.id) ELSE 0 END as average_profit, CASE WHEN SUM(o.total_cost) > 0 THEN (SUM(o.total_amount - o.total_cost) / SUM(o.total_cost)) * 100 ELSE 0 END as profitability_ratio `). Where("o.organization_id = ?", organizationID). Where("o.status = ?", entities.OrderStatusCompleted). Where("o.payment_status = ?", entities.PaymentStatusCompleted). Where("o.is_void = false AND o.is_refund = false"). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo) if outletID != nil { summaryQuery = summaryQuery.Where("o.outlet_id = ?", *outletID) } err := summaryQuery.Scan(&summary).Error if err != nil { return nil, err } // Time series data query var timeFormat string switch groupBy { case "hour": timeFormat = "DATE_TRUNC('hour', o.created_at)" case "week": timeFormat = "DATE_TRUNC('week', o.created_at)" case "month": timeFormat = "DATE_TRUNC('month', o.created_at)" default: // day timeFormat = "DATE_TRUNC('day', o.created_at)" } var data []entities.ProfitLossData dataQuery := r.db.WithContext(ctx). Table("orders o"). Select(` `+timeFormat+` as date, COALESCE(SUM(o.total_amount), 0) as revenue, COALESCE(SUM(o.total_cost), 0) as cost, COALESCE(SUM(o.total_amount - o.total_cost), 0) as gross_profit, CASE WHEN SUM(o.total_amount) > 0 THEN (SUM(o.total_amount - o.total_cost) / SUM(o.total_amount)) * 100 ELSE 0 END as gross_profit_margin, COALESCE(SUM(o.tax_amount), 0) as tax, COALESCE(SUM(o.discount_amount), 0) as discount, COALESCE(SUM(o.total_amount - o.total_cost - o.discount_amount), 0) as net_profit, CASE WHEN SUM(o.total_amount) > 0 THEN (SUM(o.total_amount - o.total_cost - o.discount_amount) / SUM(o.total_amount)) * 100 ELSE 0 END as net_profit_margin, COUNT(o.id) as orders `). Where("o.organization_id = ?", organizationID). Where("o.status = ?", entities.OrderStatusCompleted). Where("o.payment_status = ?", entities.PaymentStatusCompleted). Where("o.is_void = false AND o.is_refund = false"). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo). Group(timeFormat). Order(timeFormat) if outletID != nil { dataQuery = dataQuery.Where("o.outlet_id = ?", *outletID) } err = dataQuery.Scan(&data).Error if err != nil { return nil, err } // Product profit data query var productData []entities.ProductProfitData productQuery := r.db.WithContext(ctx). Table("order_items oi"). Select(` p.id as product_id, p.name as product_name, c.id as category_id, c.name as category_name, SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.quantity - COALESCE(oi.refund_quantity, 0) ELSE 0 END) as quantity_sold, SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.total_price - COALESCE(oi.refund_amount, 0) ELSE 0 END) as revenue, SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.total_cost * ((oi.quantity - COALESCE(oi.refund_quantity, 0))::float / NULLIF(oi.quantity, 0)) ELSE 0 END) as cost, SUM(CASE WHEN oi.is_fully_refunded = false THEN (oi.total_price - COALESCE(oi.refund_amount, 0)) - (oi.total_cost * ((oi.quantity - COALESCE(oi.refund_quantity, 0))::float / NULLIF(oi.quantity, 0))) ELSE 0 END) as gross_profit, CASE WHEN SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.total_price - COALESCE(oi.refund_amount, 0) ELSE 0 END) > 0 THEN (SUM(CASE WHEN oi.is_fully_refunded = false THEN (oi.total_price - COALESCE(oi.refund_amount, 0)) - (oi.total_cost * ((oi.quantity - COALESCE(oi.refund_quantity, 0))::float / NULLIF(oi.quantity, 0))) ELSE 0 END) / SUM(CASE WHEN oi.is_fully_refunded = false THEN oi.total_price - COALESCE(oi.refund_amount, 0) ELSE 0 END)) * 100 ELSE 0 END as gross_profit_margin, AVG(CASE WHEN oi.is_fully_refunded = false THEN oi.unit_price ELSE NULL END) as average_price, AVG(CASE WHEN oi.is_fully_refunded = false THEN oi.unit_cost ELSE NULL END) as average_cost, AVG(CASE WHEN oi.is_fully_refunded = false THEN oi.unit_price - oi.unit_cost ELSE NULL END) as profit_per_unit `). Joins("JOIN orders o ON oi.order_id = o.id"). Joins("JOIN products p ON oi.product_id = p.id"). Joins("JOIN categories c ON p.category_id = c.id"). Where("o.organization_id = ?", organizationID). Where("o.status = ?", entities.OrderStatusCompleted). Where("o.payment_status = ?", entities.PaymentStatusCompleted). Where("o.is_void = false AND o.is_refund = false"). Where("oi.status != ?", entities.OrderItemStatusCancelled). Where("o.created_at >= ? AND o.created_at <= ?", dateFrom, dateTo). Group("p.id, p.name, c.id, c.name"). Order("p.name ASC"). Limit(1000) if outletID != nil { productQuery = productQuery.Where("o.outlet_id = ?", *outletID) } err = productQuery.Scan(&productData).Error if err != nil { return nil, err } return &entities.ProfitLossAnalytics{ Summary: summary, Data: data, ProductData: productData, }, nil }