Files
animaltrack/migrations/0003-animal-registry-schema.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

58 lines
2.9 KiB
SQL

-- ABOUTME: Creates animal tracking tables for the registry system.
-- ABOUTME: Includes animal_registry, live_animals_by_location, and animal_aliases.
-- Main snapshot table for all animals (current state)
CREATE TABLE animal_registry (
animal_id TEXT PRIMARY KEY CHECK(length(animal_id) = 26),
species_code TEXT NOT NULL REFERENCES species(code),
identified INTEGER NOT NULL DEFAULT 0 CHECK(identified IN (0, 1)),
nickname TEXT,
sex TEXT NOT NULL CHECK(sex IN ('male', 'female', 'unknown')),
repro_status TEXT NOT NULL CHECK(repro_status IN ('intact', 'wether', 'spayed', 'unknown')),
life_stage TEXT NOT NULL CHECK(life_stage IN ('hatchling', 'juvenile', 'subadult', 'adult')),
status TEXT NOT NULL CHECK(status IN ('alive', 'dead', 'harvested', 'sold', 'merged_into')),
location_id TEXT NOT NULL REFERENCES locations(id),
origin TEXT NOT NULL CHECK(origin IN ('hatched', 'purchased', 'rescued', 'unknown')),
born_or_hatched_at INTEGER,
acquired_at INTEGER,
first_seen_utc INTEGER NOT NULL,
last_event_utc INTEGER NOT NULL
);
-- Unique nickname only for active animals (allows nulls, allows reuse for dead/merged)
CREATE UNIQUE INDEX idx_ar_nickname_active
ON animal_registry(nickname)
WHERE nickname IS NOT NULL
AND status NOT IN ('dead', 'harvested', 'sold', 'merged_into');
CREATE INDEX idx_ar_location ON animal_registry(location_id);
CREATE INDEX idx_ar_filter ON animal_registry(species_code, sex, life_stage, identified);
CREATE INDEX idx_ar_status ON animal_registry(status);
CREATE INDEX idx_ar_last_event ON animal_registry(last_event_utc);
-- Denormalized view for fast roster queries (only alive animals)
CREATE TABLE live_animals_by_location (
animal_id TEXT PRIMARY KEY CHECK(length(animal_id) = 26),
location_id TEXT NOT NULL REFERENCES locations(id),
species_code TEXT NOT NULL REFERENCES species(code),
identified INTEGER NOT NULL DEFAULT 0 CHECK(identified IN (0, 1)),
nickname TEXT,
sex TEXT NOT NULL CHECK(sex IN ('male', 'female', 'unknown')),
repro_status TEXT NOT NULL CHECK(repro_status IN ('intact', 'wether', 'spayed', 'unknown')),
life_stage TEXT NOT NULL CHECK(life_stage IN ('hatchling', 'juvenile', 'subadult', 'adult')),
first_seen_utc INTEGER NOT NULL,
last_move_utc INTEGER,
tags TEXT NOT NULL DEFAULT '[]' CHECK(json_valid(tags))
);
CREATE INDEX idx_labl_location ON live_animals_by_location(location_id);
CREATE INDEX idx_labl_filter ON live_animals_by_location(location_id, species_code, sex, life_stage, identified);
-- Tracks when animals are discovered to be the same individual (merge)
CREATE TABLE animal_aliases (
alias_animal_id TEXT PRIMARY KEY CHECK(length(alias_animal_id) = 26),
survivor_animal_id TEXT NOT NULL CHECK(length(survivor_animal_id) = 26),
merged_at_utc INTEGER NOT NULL
);
CREATE INDEX idx_aa_survivor ON animal_aliases(survivor_animal_id);