-- ABOUTME: Removes subadult life stage, migrating existing records to juvenile. -- ABOUTME: Updates CHECK constraints on animal_registry and live_animals_by_location. -- Update existing subadult animals to juvenile in animal_registry UPDATE animal_registry SET life_stage = 'juvenile' WHERE life_stage = 'subadult'; -- Update existing subadult animals in live_animals_by_location UPDATE live_animals_by_location SET life_stage = 'juvenile' WHERE life_stage = 'subadult'; -- SQLite doesn't support ALTER TABLE to modify CHECK constraints -- We need to recreate the tables with the updated constraint -- Step 1: Recreate animal_registry table CREATE TABLE animal_registry_new ( 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', '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 ); INSERT INTO animal_registry_new SELECT * FROM animal_registry; DROP TABLE animal_registry; ALTER TABLE animal_registry_new RENAME TO animal_registry; -- Recreate indexes for animal_registry 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); -- Step 2: Recreate live_animals_by_location table CREATE TABLE live_animals_by_location_new ( 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', 'adult')), first_seen_utc INTEGER NOT NULL, last_move_utc INTEGER, tags TEXT NOT NULL DEFAULT '[]' CHECK(json_valid(tags)) ); INSERT INTO live_animals_by_location_new SELECT * FROM live_animals_by_location; DROP TABLE live_animals_by_location; ALTER TABLE live_animals_by_location_new RENAME TO live_animals_by_location; -- Recreate indexes for live_animals_by_location 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);