Add comprehensive project documentation and Docker infrastructure for Paper Dynasty Real-Time Game Engine - a web-based multiplayer baseball simulation platform replacing the legacy Google Sheets system. Documentation Added: - Complete PRD (Product Requirements Document) - Project README with dual development workflows - Implementation guide with 5-phase roadmap - Architecture docs (backend, frontend, database, WebSocket) - CLAUDE.md context files for each major directory Infrastructure Added: - Root docker-compose.yml for full stack orchestration - Dockerfiles for backend and both frontends (multi-stage builds) - .dockerignore files for optimal build context - .env.example with all required configuration - Updated .gitignore for Python, Node, Nuxt, and Docker Project Structure: - backend/ - FastAPI + Socket.io game engine (Python 3.11+) - frontend-sba/ - SBA League Nuxt 3 frontend - frontend-pd/ - PD League Nuxt 3 frontend - .claude/implementation/ - Detailed implementation guides Supports two development workflows: 1. Local dev (recommended): Services run natively with hot-reload 2. Full Docker: One-command stack orchestration for testing/demos Next: Phase 1 implementation (backend/frontend foundations)
687 lines
15 KiB
Markdown
687 lines
15 KiB
Markdown
# Database Design
|
|
|
|
## Overview
|
|
|
|
PostgreSQL database for persistent storage of game data, play history, and session management. Designed for fast writes (async) and efficient recovery.
|
|
|
|
## Schema
|
|
|
|
### Games Table
|
|
|
|
Stores game metadata and current state.
|
|
|
|
```sql
|
|
CREATE TABLE games (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
league_id VARCHAR(50) NOT NULL,
|
|
home_team_id INTEGER NOT NULL,
|
|
away_team_id INTEGER NOT NULL,
|
|
status VARCHAR(20) NOT NULL DEFAULT 'pending',
|
|
game_mode VARCHAR(20) NOT NULL,
|
|
visibility VARCHAR(20) NOT NULL,
|
|
current_inning INTEGER,
|
|
current_half VARCHAR(10),
|
|
home_score INTEGER DEFAULT 0,
|
|
away_score INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP DEFAULT NOW(),
|
|
started_at TIMESTAMP,
|
|
completed_at TIMESTAMP,
|
|
winner_team_id INTEGER,
|
|
metadata JSONB DEFAULT '{}'::jsonb
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_games_league ON games(league_id);
|
|
CREATE INDEX idx_games_status ON games(status);
|
|
CREATE INDEX idx_games_teams ON games(home_team_id, away_team_id);
|
|
CREATE INDEX idx_games_created ON games(created_at DESC);
|
|
|
|
-- Comments
|
|
COMMENT ON COLUMN games.status IS 'pending, active, completed, abandoned';
|
|
COMMENT ON COLUMN games.game_mode IS 'live, async, vs_ai';
|
|
COMMENT ON COLUMN games.visibility IS 'public, private';
|
|
COMMENT ON COLUMN games.metadata IS 'League-specific data, config version, etc.';
|
|
```
|
|
|
|
### Plays Table
|
|
|
|
Records every play that occurs in a game.
|
|
|
|
```sql
|
|
CREATE TABLE plays (
|
|
id SERIAL PRIMARY KEY,
|
|
game_id UUID NOT NULL REFERENCES games(id) ON DELETE CASCADE,
|
|
play_number INTEGER NOT NULL,
|
|
inning INTEGER NOT NULL,
|
|
half VARCHAR(10) NOT NULL,
|
|
outs_before INTEGER NOT NULL,
|
|
outs_recorded INTEGER NOT NULL,
|
|
batter_id INTEGER NOT NULL,
|
|
pitcher_id INTEGER NOT NULL,
|
|
runners_before JSONB,
|
|
runners_after JSONB,
|
|
balls INTEGER,
|
|
strikes INTEGER,
|
|
defensive_positioning VARCHAR(50),
|
|
offensive_approach VARCHAR(50),
|
|
dice_roll INTEGER,
|
|
hit_type VARCHAR(50),
|
|
result_description TEXT,
|
|
runs_scored INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP DEFAULT NOW(),
|
|
metadata JSONB DEFAULT '{}'::jsonb,
|
|
|
|
UNIQUE(game_id, play_number)
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_plays_game ON plays(game_id);
|
|
CREATE INDEX idx_plays_game_number ON plays(game_id, play_number);
|
|
CREATE INDEX idx_plays_created ON plays(created_at);
|
|
|
|
-- Comments
|
|
COMMENT ON COLUMN plays.half IS 'top or bottom';
|
|
COMMENT ON COLUMN plays.runners_before IS '{"first": card_id, "second": null, "third": card_id}';
|
|
COMMENT ON COLUMN plays.hit_type IS 'single, double, triple, homerun, out, walk, strikeout, etc.';
|
|
COMMENT ON COLUMN plays.metadata IS 'Additional play data, stolen base results, etc.';
|
|
```
|
|
|
|
### Lineups Table
|
|
|
|
Stores lineup information for each game.
|
|
|
|
```sql
|
|
CREATE TABLE lineups (
|
|
id SERIAL PRIMARY KEY,
|
|
game_id UUID NOT NULL REFERENCES games(id) ON DELETE CASCADE,
|
|
team_id INTEGER NOT NULL,
|
|
card_id INTEGER NOT NULL,
|
|
position VARCHAR(10) NOT NULL,
|
|
batting_order INTEGER,
|
|
is_starter BOOLEAN DEFAULT TRUE,
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
entered_inning INTEGER DEFAULT 1,
|
|
metadata JSONB DEFAULT '{}'::jsonb
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_lineups_game ON lineups(game_id);
|
|
CREATE INDEX idx_lineups_team ON lineups(team_id);
|
|
CREATE INDEX idx_lineups_active ON lineups(game_id, is_active);
|
|
CREATE INDEX idx_lineups_game_team ON lineups(game_id, team_id);
|
|
|
|
-- Comments
|
|
COMMENT ON COLUMN lineups.position IS 'P, C, 1B, 2B, 3B, SS, LF, CF, RF, DH';
|
|
COMMENT ON COLUMN lineups.is_active IS 'FALSE when substituted out';
|
|
COMMENT ON COLUMN lineups.entered_inning IS 'Inning when player entered game';
|
|
```
|
|
|
|
### Game Sessions Table
|
|
|
|
Tracks active WebSocket sessions and state snapshots.
|
|
|
|
```sql
|
|
CREATE TABLE game_sessions (
|
|
game_id UUID PRIMARY KEY REFERENCES games(id) ON DELETE CASCADE,
|
|
connected_users JSONB DEFAULT '{}'::jsonb,
|
|
last_action_at TIMESTAMP DEFAULT NOW(),
|
|
state_snapshot JSONB DEFAULT '{}'::jsonb,
|
|
updated_at TIMESTAMP DEFAULT NOW()
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_sessions_last_action ON game_sessions(last_action_at);
|
|
|
|
-- Comments
|
|
COMMENT ON COLUMN game_sessions.connected_users IS '{"user_id": {"role": "home_gm", "last_seen": "timestamp"}}';
|
|
COMMENT ON COLUMN game_sessions.state_snapshot IS 'Full game state for quick recovery';
|
|
```
|
|
|
|
### Users Table (Optional - if not using external auth exclusively)
|
|
|
|
```sql
|
|
CREATE TABLE users (
|
|
id SERIAL PRIMARY KEY,
|
|
discord_id VARCHAR(50) UNIQUE NOT NULL,
|
|
discord_username VARCHAR(100),
|
|
discord_avatar VARCHAR(255),
|
|
created_at TIMESTAMP DEFAULT NOW(),
|
|
last_login TIMESTAMP,
|
|
metadata JSONB DEFAULT '{}'::jsonb
|
|
);
|
|
|
|
-- Indexes
|
|
CREATE INDEX idx_users_discord ON users(discord_id);
|
|
|
|
-- Comments
|
|
COMMENT ON TABLE users IS 'Optional user cache if needed for offline queries';
|
|
```
|
|
|
|
## Data Types & Constraints
|
|
|
|
### JSONB Fields
|
|
|
|
#### games.metadata
|
|
```json
|
|
{
|
|
"league_config_version": "1.0",
|
|
"home_gm_id": "discord_snowflake_123",
|
|
"away_gm_id": "discord_snowflake_456",
|
|
"home_gm_ready": true,
|
|
"away_gm_ready": false,
|
|
"starting_pitcher_home": 12345,
|
|
"starting_pitcher_away": 67890
|
|
}
|
|
```
|
|
|
|
#### plays.runners_before / runners_after
|
|
```json
|
|
{
|
|
"first": 12345, // card_id or null
|
|
"second": null,
|
|
"third": 67890
|
|
}
|
|
```
|
|
|
|
#### plays.metadata
|
|
```json
|
|
{
|
|
"stolen_base_attempts": {
|
|
"second": true,
|
|
"third": false
|
|
},
|
|
"stolen_base_results": {
|
|
"second": "safe"
|
|
},
|
|
"hit_location": "left_field",
|
|
"fielder": 54321
|
|
}
|
|
```
|
|
|
|
#### lineups.metadata
|
|
```json
|
|
{
|
|
"substitution_reason": "pinch_hitter",
|
|
"replaced_card_id": 11111,
|
|
"pitcher_stats": {
|
|
"innings_pitched": 6.0,
|
|
"hits_allowed": 4,
|
|
"runs_allowed": 1
|
|
}
|
|
}
|
|
```
|
|
|
|
#### game_sessions.state_snapshot
|
|
```json
|
|
{
|
|
"inning": 3,
|
|
"half": "top",
|
|
"outs": 2,
|
|
"balls": 2,
|
|
"strikes": 1,
|
|
"home_score": 2,
|
|
"away_score": 1,
|
|
"runners": {"first": null, "second": 12345, "third": null},
|
|
"current_batter_idx": 3,
|
|
"current_decisions": {}
|
|
}
|
|
```
|
|
|
|
## Queries
|
|
|
|
### Common Read Queries
|
|
|
|
#### Get Game with Latest Play
|
|
```sql
|
|
SELECT
|
|
g.*,
|
|
p.play_number as last_play,
|
|
p.result_description as last_play_description
|
|
FROM games g
|
|
LEFT JOIN LATERAL (
|
|
SELECT * FROM plays
|
|
WHERE game_id = g.id
|
|
ORDER BY play_number DESC
|
|
LIMIT 1
|
|
) p ON TRUE
|
|
WHERE g.id = $1;
|
|
```
|
|
|
|
#### Get Active Lineup for Team
|
|
```sql
|
|
SELECT
|
|
l.*,
|
|
l.batting_order,
|
|
l.position
|
|
FROM lineups l
|
|
WHERE l.game_id = $1
|
|
AND l.team_id = $2
|
|
AND l.is_active = TRUE
|
|
ORDER BY l.batting_order NULLS LAST;
|
|
```
|
|
|
|
#### Get Play History for Game
|
|
```sql
|
|
SELECT
|
|
play_number,
|
|
inning,
|
|
half,
|
|
outs_before,
|
|
batter_id,
|
|
pitcher_id,
|
|
dice_roll,
|
|
hit_type,
|
|
result_description,
|
|
runs_scored,
|
|
created_at
|
|
FROM plays
|
|
WHERE game_id = $1
|
|
ORDER BY play_number;
|
|
```
|
|
|
|
#### Get Active Games for User
|
|
```sql
|
|
SELECT
|
|
g.*,
|
|
CASE
|
|
WHEN g.home_team_id = ANY($2) THEN 'home'
|
|
WHEN g.away_team_id = ANY($2) THEN 'away'
|
|
END as role,
|
|
(SELECT COUNT(*) FROM plays WHERE game_id = g.id) as play_count
|
|
FROM games g
|
|
WHERE g.status IN ('pending', 'active')
|
|
AND (g.home_team_id = ANY($2) OR g.away_team_id = ANY($2))
|
|
ORDER BY g.created_at DESC;
|
|
|
|
-- $1 = user_id, $2 = array of team_ids user owns
|
|
```
|
|
|
|
#### Get Recent Completed Games
|
|
```sql
|
|
SELECT
|
|
g.id,
|
|
g.league_id,
|
|
g.home_team_id,
|
|
g.away_team_id,
|
|
g.home_score,
|
|
g.away_score,
|
|
g.winner_team_id,
|
|
g.completed_at,
|
|
EXTRACT(EPOCH FROM (g.completed_at - g.started_at))/60 as duration_minutes
|
|
FROM games g
|
|
WHERE g.status = 'completed'
|
|
AND g.league_id = $1
|
|
ORDER BY g.completed_at DESC
|
|
LIMIT 50;
|
|
```
|
|
|
|
### Common Write Queries
|
|
|
|
#### Create New Game
|
|
```sql
|
|
INSERT INTO games (
|
|
league_id,
|
|
home_team_id,
|
|
away_team_id,
|
|
status,
|
|
game_mode,
|
|
visibility,
|
|
metadata
|
|
) VALUES (
|
|
$1, $2, $3, 'pending', $4, $5, $6
|
|
)
|
|
RETURNING id;
|
|
```
|
|
|
|
#### Insert Play
|
|
```sql
|
|
INSERT INTO plays (
|
|
game_id,
|
|
play_number,
|
|
inning,
|
|
half,
|
|
outs_before,
|
|
outs_recorded,
|
|
batter_id,
|
|
pitcher_id,
|
|
runners_before,
|
|
runners_after,
|
|
balls,
|
|
strikes,
|
|
defensive_positioning,
|
|
offensive_approach,
|
|
dice_roll,
|
|
hit_type,
|
|
result_description,
|
|
runs_scored,
|
|
metadata
|
|
) VALUES (
|
|
$1, $2, $3, $4, $5, $6, $7, $8, $9, $10,
|
|
$11, $12, $13, $14, $15, $16, $17, $18, $19
|
|
)
|
|
RETURNING id;
|
|
```
|
|
|
|
#### Update Game Score
|
|
```sql
|
|
UPDATE games
|
|
SET
|
|
current_inning = $2,
|
|
current_half = $3,
|
|
home_score = $4,
|
|
away_score = $5
|
|
WHERE id = $1;
|
|
```
|
|
|
|
#### Make Substitution
|
|
```sql
|
|
-- Deactivate old player
|
|
UPDATE lineups
|
|
SET is_active = FALSE
|
|
WHERE game_id = $1
|
|
AND card_id = $2;
|
|
|
|
-- Insert new player
|
|
INSERT INTO lineups (
|
|
game_id,
|
|
team_id,
|
|
card_id,
|
|
position,
|
|
batting_order,
|
|
is_starter,
|
|
is_active,
|
|
entered_inning
|
|
) VALUES (
|
|
$1, $3, $4, $5, $6, FALSE, TRUE, $7
|
|
);
|
|
```
|
|
|
|
#### Complete Game
|
|
```sql
|
|
UPDATE games
|
|
SET
|
|
status = 'completed',
|
|
completed_at = NOW(),
|
|
winner_team_id = $2
|
|
WHERE id = $1;
|
|
```
|
|
|
|
### State Recovery Query
|
|
|
|
```sql
|
|
-- Get all data needed to rebuild game state
|
|
WITH game_info AS (
|
|
SELECT * FROM games WHERE id = $1
|
|
),
|
|
lineup_data AS (
|
|
SELECT * FROM lineups WHERE game_id = $1 AND is_active = TRUE
|
|
),
|
|
play_data AS (
|
|
SELECT * FROM plays WHERE game_id = $1 ORDER BY play_number
|
|
)
|
|
SELECT
|
|
json_build_object(
|
|
'game', (SELECT row_to_json(g) FROM game_info g),
|
|
'lineups', (SELECT json_agg(l) FROM lineup_data l),
|
|
'plays', (SELECT json_agg(p) FROM play_data p)
|
|
) as game_state;
|
|
```
|
|
|
|
## Performance Optimization
|
|
|
|
### Index Strategy
|
|
|
|
**Games Table**:
|
|
- `idx_games_league`: Filter by league
|
|
- `idx_games_status`: Find active/completed games
|
|
- `idx_games_teams`: Find games by team
|
|
- `idx_games_created`: Recent games list
|
|
|
|
**Plays Table**:
|
|
- `idx_plays_game`: All plays for a game (most common)
|
|
- `idx_plays_game_number`: Specific play lookup
|
|
- `idx_plays_created`: Recent plays across all games
|
|
|
|
**Lineups Table**:
|
|
- `idx_lineups_game`: All lineups for a game
|
|
- `idx_lineups_team`: Team's lineup across games
|
|
- `idx_lineups_active`: Active players only
|
|
- `idx_lineups_game_team`: Combined filter (most efficient)
|
|
|
|
### Query Optimization Tips
|
|
|
|
1. **Use EXPLAIN ANALYZE** for slow queries
|
|
2. **Avoid SELECT \***: Specify needed columns
|
|
3. **Use LATERAL joins** for correlated subqueries
|
|
4. **Leverage JSONB indexes** if filtering on metadata fields frequently
|
|
5. **Partition plays table** if growing very large (by created_at)
|
|
|
|
### Connection Pooling
|
|
|
|
```python
|
|
# SQLAlchemy async engine with connection pooling
|
|
engine = create_async_engine(
|
|
database_url,
|
|
pool_size=20, # Number of persistent connections
|
|
max_overflow=10, # Additional connections when needed
|
|
pool_timeout=30, # Seconds to wait for connection
|
|
pool_recycle=3600, # Recycle connections after 1 hour
|
|
pool_pre_ping=True # Verify connection health before use
|
|
)
|
|
```
|
|
|
|
## Data Integrity
|
|
|
|
### Foreign Key Constraints
|
|
|
|
All foreign keys include `ON DELETE CASCADE` to ensure referential integrity:
|
|
- When a game is deleted, all plays and lineups are automatically deleted
|
|
- Prevents orphaned records
|
|
|
|
### Check Constraints
|
|
|
|
```sql
|
|
-- Add validation constraints
|
|
ALTER TABLE games
|
|
ADD CONSTRAINT check_status
|
|
CHECK (status IN ('pending', 'active', 'completed', 'abandoned'));
|
|
|
|
ALTER TABLE games
|
|
ADD CONSTRAINT check_game_mode
|
|
CHECK (game_mode IN ('live', 'async', 'vs_ai'));
|
|
|
|
ALTER TABLE games
|
|
ADD CONSTRAINT check_scores
|
|
CHECK (home_score >= 0 AND away_score >= 0);
|
|
|
|
ALTER TABLE plays
|
|
ADD CONSTRAINT check_half
|
|
CHECK (half IN ('top', 'bottom'));
|
|
|
|
ALTER TABLE plays
|
|
ADD CONSTRAINT check_outs
|
|
CHECK (outs_before >= 0 AND outs_before <= 2 AND outs_recorded >= 0);
|
|
|
|
ALTER TABLE lineups
|
|
ADD CONSTRAINT check_position
|
|
CHECK (position IN ('P', 'C', '1B', '2B', '3B', 'SS', 'LF', 'CF', 'RF', 'DH'));
|
|
```
|
|
|
|
## Backup & Recovery
|
|
|
|
### Daily Backups
|
|
|
|
```bash
|
|
#!/bin/bash
|
|
# daily-backup.sh
|
|
|
|
DATE=$(date +%Y%m%d)
|
|
BACKUP_DIR="/backups/paperdynasty"
|
|
DB_NAME="paperdynasty"
|
|
|
|
# Create backup directory
|
|
mkdir -p $BACKUP_DIR
|
|
|
|
# Full database backup
|
|
pg_dump -U paperdynasty -F c -b -v -f "$BACKUP_DIR/full_backup_$DATE.dump" $DB_NAME
|
|
|
|
# Compress
|
|
gzip "$BACKUP_DIR/full_backup_$DATE.dump"
|
|
|
|
# Keep only last 30 days
|
|
find $BACKUP_DIR -name "full_backup_*.dump.gz" -mtime +30 -delete
|
|
|
|
echo "Backup completed: $DATE"
|
|
```
|
|
|
|
### Point-in-Time Recovery Setup
|
|
|
|
```sql
|
|
-- Enable WAL archiving (postgresql.conf)
|
|
wal_level = replica
|
|
archive_mode = on
|
|
archive_command = 'cp %p /var/lib/postgresql/wal_archive/%f'
|
|
```
|
|
|
|
### Recovery Procedure
|
|
|
|
```bash
|
|
# Restore from backup
|
|
pg_restore -U paperdynasty -d paperdynasty -c backup_file.dump
|
|
|
|
# Verify data
|
|
psql -U paperdynasty -d paperdynasty -c "SELECT COUNT(*) FROM games;"
|
|
```
|
|
|
|
## Migration Strategy
|
|
|
|
### Using Alembic
|
|
|
|
```bash
|
|
# Initialize Alembic
|
|
cd backend
|
|
alembic init alembic
|
|
|
|
# Create migration
|
|
alembic revision -m "create initial tables"
|
|
|
|
# Apply migration
|
|
alembic upgrade head
|
|
|
|
# Rollback
|
|
alembic downgrade -1
|
|
```
|
|
|
|
### Example Migration
|
|
|
|
```python
|
|
# alembic/versions/001_create_initial_tables.py
|
|
from alembic import op
|
|
import sqlalchemy as sa
|
|
from sqlalchemy.dialects.postgresql import UUID, JSONB
|
|
|
|
def upgrade():
|
|
op.create_table(
|
|
'games',
|
|
sa.Column('id', UUID(as_uuid=True), primary_key=True),
|
|
sa.Column('league_id', sa.String(50), nullable=False),
|
|
# ... other columns
|
|
)
|
|
|
|
# Create indexes
|
|
op.create_index('idx_games_league', 'games', ['league_id'])
|
|
op.create_index('idx_games_status', 'games', ['status'])
|
|
|
|
def downgrade():
|
|
op.drop_table('games')
|
|
```
|
|
|
|
## Monitoring Queries
|
|
|
|
### Active Connections
|
|
```sql
|
|
SELECT
|
|
count(*) as total_connections,
|
|
count(*) FILTER (WHERE state = 'active') as active_queries,
|
|
count(*) FILTER (WHERE state = 'idle') as idle_connections
|
|
FROM pg_stat_activity
|
|
WHERE datname = 'paperdynasty';
|
|
```
|
|
|
|
### Slow Queries
|
|
```sql
|
|
SELECT
|
|
query,
|
|
calls,
|
|
mean_exec_time,
|
|
max_exec_time,
|
|
total_exec_time
|
|
FROM pg_stat_statements
|
|
WHERE query LIKE '%games%'
|
|
ORDER BY mean_exec_time DESC
|
|
LIMIT 10;
|
|
```
|
|
|
|
### Table Sizes
|
|
```sql
|
|
SELECT
|
|
tablename,
|
|
pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) AS size
|
|
FROM pg_tables
|
|
WHERE schemaname = 'public'
|
|
ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC;
|
|
```
|
|
|
|
### Index Usage
|
|
```sql
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
indexname,
|
|
idx_scan as index_scans,
|
|
idx_tup_read as tuples_read,
|
|
idx_tup_fetch as tuples_fetched
|
|
FROM pg_stat_user_indexes
|
|
WHERE schemaname = 'public'
|
|
ORDER BY idx_scan DESC;
|
|
```
|
|
|
|
## Testing Data
|
|
|
|
### Seed Development Data
|
|
|
|
```sql
|
|
-- Insert test game
|
|
INSERT INTO games (id, league_id, home_team_id, away_team_id, status, game_mode, visibility)
|
|
VALUES (
|
|
'550e8400-e29b-41d4-a716-446655440000',
|
|
'sba',
|
|
1,
|
|
2,
|
|
'active',
|
|
'live',
|
|
'public'
|
|
);
|
|
|
|
-- Insert test lineups
|
|
INSERT INTO lineups (game_id, team_id, card_id, position, batting_order, is_starter, is_active)
|
|
VALUES
|
|
('550e8400-e29b-41d4-a716-446655440000', 1, 101, 'P', NULL, TRUE, TRUE),
|
|
('550e8400-e29b-41d4-a716-446655440000', 1, 102, 'C', 9, TRUE, TRUE),
|
|
('550e8400-e29b-41d4-a716-446655440000', 1, 103, 'CF', 1, TRUE, TRUE);
|
|
-- ... more players
|
|
|
|
-- Insert test play
|
|
INSERT INTO plays (
|
|
game_id, play_number, inning, half, outs_before, outs_recorded,
|
|
batter_id, pitcher_id, dice_roll, hit_type, result_description, runs_scored
|
|
) VALUES (
|
|
'550e8400-e29b-41d4-a716-446655440000',
|
|
1, 1, 'top', 0, 1, 103, 201, 5, 'groundout',
|
|
'Groundout to shortstop', 0
|
|
);
|
|
```
|
|
|
|
---
|
|
|
|
**Next Steps**: See [01-infrastructure.md](./01-infrastructure.md) for database setup instructions. |