Files
animaltrack/migrations/0004-interval-projections.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.1 KiB
SQL

-- ABOUTME: Creates interval projection tables for time-series tracking.
-- ABOUTME: Tracks animal location, tag, and attribute history over time.
-- Track animal location history
-- Each row represents a period when an animal was at a specific location
CREATE TABLE animal_location_intervals (
animal_id TEXT NOT NULL CHECK(length(animal_id) = 26),
location_id TEXT NOT NULL CHECK(length(location_id) = 26),
start_utc INTEGER NOT NULL,
end_utc INTEGER,
PRIMARY KEY (animal_id, start_utc),
CHECK(end_utc IS NULL OR end_utc > start_utc)
);
-- Index for "which animals were at location X at time T" queries
CREATE INDEX idx_ali_loc_time ON animal_location_intervals(
location_id, start_utc, COALESCE(end_utc, 32503680000000)
);
-- Index for "where was animal X at time T" queries
CREATE INDEX idx_ali_animal_time ON animal_location_intervals(
animal_id, start_utc, COALESCE(end_utc, 32503680000000)
);
-- Track animal tag history
-- Each row represents a period when an animal had a specific tag
CREATE TABLE animal_tag_intervals (
animal_id TEXT NOT NULL CHECK(length(animal_id) = 26),
tag TEXT NOT NULL,
start_utc INTEGER NOT NULL,
end_utc INTEGER,
PRIMARY KEY (animal_id, tag, start_utc),
CHECK(end_utc IS NULL OR end_utc > start_utc)
);
-- Index for "which animals had tag X at time T" queries
CREATE INDEX idx_ati_tag_time ON animal_tag_intervals(
tag, start_utc, COALESCE(end_utc, 32503680000000)
);
-- Track attribute changes (sex, life_stage, repro_status, status)
-- Each row represents a period when an animal had a specific attribute value
CREATE TABLE animal_attr_intervals (
animal_id TEXT NOT NULL CHECK(length(animal_id) = 26),
attr TEXT NOT NULL CHECK(attr IN ('sex', 'life_stage', 'repro_status', 'status')),
value TEXT NOT NULL,
start_utc INTEGER NOT NULL,
end_utc INTEGER,
PRIMARY KEY (animal_id, attr, start_utc),
CHECK(end_utc IS NULL OR end_utc > start_utc)
);
-- Index for "which animals had attr=value at time T" queries
CREATE INDEX idx_aai_attr_time ON animal_attr_intervals(
attr, value, start_utc, COALESCE(end_utc, 32503680000000)
);