Files
animaltrack/migrations/0002-event-tables.sql
Petru Paler 25a91c3322 fix: remove trailing newlines from migrations to prevent SQLITE_MISUSE errors
Python's sqlite3.executescript() has a bug where trailing newlines after
the final semicolon create empty statements. When APSW's log_sqlite() is
enabled (via apswutils, imported by fastmigrate), these cause visible
"API called with NULL prepared statement" errors during interpreter shutdown.

- Strip trailing newlines from all 9 existing migration files
- Update migration template to end with semicolon, no trailing newline
- Document the requirement in CLAUDE.md

🤖 Generated with [Claude Code](https://claude.com/claude-code)

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2026-01-01 16:09:06 +00:00

56 lines
2.0 KiB
SQL

-- ABOUTME: Creates event sourcing tables (events, event_revisions, event_tombstones).
-- ABOUTME: Also creates idempotency_nonces and event_animals tables.
-- events: Core event log table
CREATE TABLE events (
id TEXT PRIMARY KEY CHECK(length(id) = 26),
type TEXT NOT NULL,
ts_utc INTEGER NOT NULL,
actor TEXT NOT NULL,
entity_refs TEXT NOT NULL CHECK(json_valid(entity_refs)),
payload TEXT NOT NULL CHECK(json_valid(payload)),
version INTEGER NOT NULL DEFAULT 1
);
CREATE INDEX idx_events_ts ON events(ts_utc);
CREATE INDEX idx_events_type_ts ON events(type, ts_utc);
CREATE INDEX idx_events_actor_ts ON events(actor, ts_utc);
-- event_revisions: Stores prior versions when events are edited
CREATE TABLE event_revisions (
event_id TEXT NOT NULL CHECK(length(event_id) = 26),
version INTEGER NOT NULL,
ts_utc INTEGER NOT NULL,
actor TEXT NOT NULL,
entity_refs TEXT NOT NULL CHECK(json_valid(entity_refs)),
payload TEXT NOT NULL CHECK(json_valid(payload)),
edited_at_utc INTEGER NOT NULL,
edited_by TEXT NOT NULL,
PRIMARY KEY (event_id, version)
);
-- event_tombstones: Immutable deletion records
CREATE TABLE event_tombstones (
id TEXT PRIMARY KEY CHECK(length(id) = 26),
ts_utc INTEGER NOT NULL,
actor TEXT NOT NULL,
target_event_id TEXT NOT NULL CHECK(length(target_event_id) = 26),
reason TEXT
);
CREATE INDEX idx_event_tombstones_target ON event_tombstones(target_event_id);
-- idempotency_nonces: Prevents duplicate POST submissions
CREATE TABLE idempotency_nonces (
nonce TEXT PRIMARY KEY,
actor TEXT NOT NULL,
route TEXT NOT NULL,
created_at_utc INTEGER NOT NULL
);
-- event_animals: Links events to affected animals
CREATE TABLE event_animals (
event_id TEXT NOT NULL CHECK(length(event_id) = 26),
animal_id TEXT NOT NULL CHECK(length(animal_id) = 26),
ts_utc INTEGER NOT NULL,
PRIMARY KEY (event_id, animal_id)
);
CREATE UNIQUE INDEX ux_event_animals_animal_ts ON event_animals(animal_id, ts_utc);