-- name: UpdateCompanyStats :exec WITH -- Aggregate bet data per company bet_stats AS ( SELECT company_id, COUNT(*) AS total_bets, COALESCE(SUM(amount), 0) AS total_stake, COALESCE( SUM(amount) * MAX(companies.deducted_percentage), 0 ) AS deducted_stake, COALESCE( SUM( CASE WHEN cashed_out THEN amount ELSE 0 END ), 0 ) AS total_cash_out, COALESCE( SUM( CASE WHEN status = 3 THEN amount ELSE 0 END ), 0 ) AS total_cash_backs, COUNT(*) FILTER ( WHERE status = 5 ) AS number_of_unsettled, COALESCE( SUM( CASE WHEN status = 5 THEN amount ELSE 0 END ), 0 ) AS total_unsettled_amount FROM shop_bet_detail LEFT JOIN companies ON companies.id = shop_bet_detail.company_id GROUP BY company_id ), -- Aggregate user counts per company user_stats AS ( SELECT company_id, COUNT(*) FILTER ( WHERE role = 'admin' ) AS total_admins, COUNT(*) FILTER ( WHERE role = 'branch_manager' ) AS total_managers, COUNT(*) FILTER ( WHERE role = 'cashier' ) AS total_cashiers, COUNT(*) FILTER ( WHERE role = 'customer' ) AS total_customers, COUNT(*) FILTER ( WHERE role = 'transaction_approver' ) AS total_approvers FROM users GROUP BY company_id ), -- Aggregate branch counts per company branch_stats AS ( SELECT company_id, COUNT(*) AS total_branches FROM branches GROUP BY company_id ) -- Final combined aggregation INSERT INTO company_stats ( company_id, interval_start, total_bets, total_stake, deducted_stake, total_cash_out, total_cash_backs, number_of_unsettled, total_unsettled_amount, total_admins, total_managers, total_cashiers, total_customers, total_approvers, total_branches, updated_at ) SELECT c.id AS company_id, DATE_TRUNC('day', NOW() AT TIME ZONE 'UTC') AS interval_start, COALESCE(b.total_bets, 0) AS total_bets, COALESCE(b.total_stake, 0) AS total_stake, COALESCE(b.deducted_stake, 0) AS deducted_stake, COALESCE(b.total_cash_out, 0) AS total_cash_out, COALESCE(b.total_cash_backs, 0) AS total_cash_backs, COALESCE(b.number_of_unsettled, 0) AS number_of_unsettled, COALESCE(b.total_unsettled_amount, 0) AS total_unsettled_amount, COALESCE(u.total_admins, 0) AS total_admins, COALESCE(u.total_managers, 0) AS total_managers, COALESCE(u.total_cashiers, 0) AS total_cashiers, COALESCE(u.total_customers, 0) AS total_customers, COALESCE(u.total_approvers, 0) AS total_approvers, COALESCE(br.total_branches, 0) AS total_branches, NOW() AS updated_at FROM companies c LEFT JOIN bet_stats b ON b.company_id = c.id LEFT JOIN user_stats u ON u.company_id = c.id LEFT JOIN branch_stats br ON br.company_id = c.id ON CONFLICT (company_id, interval_start) DO UPDATE SET total_bets = EXCLUDED.total_bets, total_stake = EXCLUDED.total_stake, deducted_stake = EXCLUDED.deducted_stake, total_cash_out = EXCLUDED.total_cash_out, total_cash_backs = EXCLUDED.total_cash_backs, number_of_unsettled = EXCLUDED.number_of_unsettled, total_unsettled_amount = EXCLUDED.total_unsettled_amount, total_admins = EXCLUDED.total_admins, total_managers = EXCLUDED.total_managers, total_cashiers = EXCLUDED.total_cashiers, total_customers = EXCLUDED.total_customers, total_approvers = EXCLUDED.total_approvers, total_branches = EXCLUDED.total_branches, updated_at = EXCLUDED.updated_at; -- name: GetCompanyStatsByID :many SELECT * FROM company_stats WHERE company_id = $1 ORDER BY interval_start DESC; -- name: GetCompanyStats :many SELECT DATE_TRUNC(sqlc.narg('interval'), interval_start)::timestamp AS interval_start, company_stats.* FROM company_stats WHERE ( company_stats.company_id = sqlc.narg('company_id') OR sqlc.narg('company_id') IS NULL ) GROUP BY interval_start ORDER BY interval_start DESC;