Yimaru-BackEnd/db/migrations/00009_virtual_reports.up.sql

74 lines
2.5 KiB
SQL

CREATE TABLE IF NOT EXISTS virtual_game_financial_reports (
id BIGSERIAL PRIMARY KEY,
game_id VARCHAR(150) NOT NULL REFERENCES virtual_games(game_id) ON DELETE CASCADE,
provider_id VARCHAR(100) NOT NULL REFERENCES virtual_game_providers(provider_id) ON DELETE CASCADE,
report_date DATE NOT NULL,
report_type VARCHAR(50) NOT NULL DEFAULT 'daily',
total_bets NUMERIC(18,2) DEFAULT 0,
total_wins NUMERIC(18,2) DEFAULT 0,
ggr NUMERIC(18,2) GENERATED ALWAYS AS (total_bets - total_wins) STORED,
rtp NUMERIC(5,2) GENERATED ALWAYS AS (
CASE WHEN total_bets > 0 THEN (total_wins / total_bets) * 100 ELSE 0 END
) STORED,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ
);
CREATE TABLE IF NOT EXISTS virtual_game_company_reports (
id BIGSERIAL PRIMARY KEY,
company_id BIGINT NOT NULL REFERENCES companies(id) ON DELETE CASCADE,
provider_id VARCHAR(100) NOT NULL REFERENCES virtual_game_providers(provider_id) ON DELETE CASCADE,
report_date DATE NOT NULL,
report_type VARCHAR(50) NOT NULL DEFAULT 'daily',
total_bet_amount NUMERIC(18,2) DEFAULT 0,
total_win_amount NUMERIC(18,2) DEFAULT 0,
net_profit NUMERIC(18,2) GENERATED ALWAYS AS (total_bet_amount - total_win_amount) STORED,
profit_margin NUMERIC(6,3) GENERATED ALWAYS AS (
CASE WHEN total_bet_amount > 0 THEN (total_bet_amount - total_win_amount) / total_bet_amount ELSE 0 END
) STORED,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ
);
CREATE TABLE IF NOT EXISTS virtual_game_player_activity_reports (
id BIGSERIAL PRIMARY KEY,
user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
-- Reporting scope
report_date DATE NOT NULL,
report_type VARCHAR(50) NOT NULL DEFAULT 'daily',
-- Cashflow information
total_deposits NUMERIC(18,2) DEFAULT 0,
total_withdrawals NUMERIC(18,2) DEFAULT 0,
net_contribution NUMERIC(18,2) GENERATED ALWAYS AS (
total_deposits - total_withdrawals
) STORED,
-- Betting and win/loss analytics
total_bet_amount NUMERIC(18,2) DEFAULT 0,
total_win_amount NUMERIC(18,2) DEFAULT 0,
net_result NUMERIC(18,2) GENERATED ALWAYS AS (
total_bet_amount - total_win_amount
) STORED,
rounds_played BIGINT DEFAULT 0,
avg_bet_size NUMERIC(18,4) GENERATED ALWAYS AS (
CASE WHEN rounds_played > 0 THEN total_bet_amount / rounds_played ELSE 0 END
) STORED,
created_at TIMESTAMPTZ NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMPTZ
);