638 lines
27 KiB
Markdown
638 lines
27 KiB
Markdown
# AnimalTrack v1 — Final Developer Spec
|
||
|
||
## 0) Scope
|
||
|
||
* Species now: `duck`, `goose`. Reserve `sheep`.
|
||
* Individuals = “animals.” Anonymous by default. Optional promotion with global-unique nickname (unique while active).
|
||
* Groups are implicit: animals currently at a location.
|
||
* Web app. Mobile-first. Self-hosted. FastHTML + HTMX + MonsterUI. SQLite.
|
||
|
||
## 1) Architecture
|
||
|
||
* Event-sourced writes → synchronous projections in the same txn.
|
||
* Time: client submits UTC `ts_utc`. DB stores UTC. UI shows Europe/Lisbon.
|
||
* IDs: server-generated ULIDs for events and entities.
|
||
* Selection filters resolve against **state at `ts_utc`**. Persist both the filter string and the resolved IDs.
|
||
* Sentinel constant: `END_OF_TIME_UTC = 32503680000000` (ms epoch for year 3000) used in interval indexes for unbounded `end_utc`.
|
||
|
||
## 2) Data model (reference tables)
|
||
|
||
```sql
|
||
CREATE TABLE species (
|
||
code TEXT PRIMARY KEY,
|
||
name TEXT NOT NULL,
|
||
active INTEGER NOT NULL DEFAULT 1 CHECK(active IN (0,1)),
|
||
created_at_utc INTEGER NOT NULL,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
|
||
CREATE TABLE locations (
|
||
id TEXT PRIMARY KEY CHECK(length(id)=26),
|
||
name TEXT NOT NULL UNIQUE,
|
||
active INTEGER NOT NULL DEFAULT 1,
|
||
created_at_utc INTEGER NOT NULL,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
|
||
CREATE TABLE products (
|
||
code TEXT PRIMARY KEY, -- e.g., egg.duck
|
||
name TEXT NOT NULL,
|
||
unit TEXT NOT NULL CHECK(unit IN ('piece','kg')),
|
||
collectable INTEGER NOT NULL CHECK(collectable IN (0,1)),
|
||
sellable INTEGER NOT NULL CHECK(sellable IN (0,1)),
|
||
active INTEGER NOT NULL DEFAULT 1 CHECK(active IN (0,1)),
|
||
created_at_utc INTEGER NOT NULL,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
|
||
CREATE TABLE feed_types (
|
||
code TEXT PRIMARY KEY,
|
||
name TEXT NOT NULL,
|
||
default_bag_size_kg INTEGER NOT NULL CHECK(default_bag_size_kg >= 1),
|
||
protein_pct REAL NULL,
|
||
active INTEGER NOT NULL DEFAULT 1 CHECK(active IN (0,1)),
|
||
created_at_utc INTEGER NOT NULL,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
|
||
CREATE TABLE users (
|
||
username TEXT PRIMARY KEY,
|
||
role TEXT NOT NULL CHECK(role IN ('admin','recorder')),
|
||
active INTEGER NOT NULL DEFAULT 1 CHECK(active IN (0,1)),
|
||
created_at_utc INTEGER NOT NULL,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
```
|
||
|
||
FK policy: **ON DELETE RESTRICT** everywhere.
|
||
|
||
## 3) Event log and controls
|
||
|
||
```sql
|
||
CREATE TABLE events (
|
||
id TEXT PRIMARY KEY CHECK(length(id)=26),
|
||
type TEXT NOT NULL, -- e.g., ProductCollected
|
||
ts_utc INTEGER NOT NULL, -- ms since epoch, authoritative
|
||
actor TEXT NOT NULL, -- from X-Oidc-Username
|
||
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);
|
||
|
||
-- Prior versions on edit
|
||
CREATE TABLE event_revisions (
|
||
event_id TEXT NOT NULL,
|
||
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)
|
||
);
|
||
|
||
-- Tombstones for deletions
|
||
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,
|
||
reason TEXT
|
||
);
|
||
CREATE INDEX idx_event_tombstones_target ON event_tombstones(target_event_id);
|
||
|
||
-- Idempotency nonces (hidden ULID per POST form)
|
||
CREATE TABLE idempotency_nonces (
|
||
nonce TEXT PRIMARY KEY,
|
||
actor TEXT NOT NULL,
|
||
route TEXT NOT NULL,
|
||
created_at_utc INTEGER NOT NULL
|
||
);
|
||
|
||
-- Enforce: no same-animal same-timestamp across all animal-targeting events
|
||
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);
|
||
```
|
||
|
||
## 4) Interval projections (for historical queries)
|
||
|
||
```sql
|
||
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)
|
||
);
|
||
CREATE INDEX idx_ali_loc_time ON animal_location_intervals(location_id, start_utc, COALESCE(end_utc, 32503680000000));
|
||
CREATE INDEX idx_ali_animal_time ON animal_location_intervals(animal_id, start_utc, COALESCE(end_utc, 32503680000000));
|
||
|
||
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)
|
||
);
|
||
CREATE INDEX idx_ati_tag_time ON animal_tag_intervals(tag, start_utc, COALESCE(end_utc, 32503680000000));
|
||
|
||
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)
|
||
);
|
||
CREATE INDEX idx_aai_attr_time ON animal_attr_intervals(attr, value, start_utc, COALESCE(end_utc, 32503680000000));
|
||
```
|
||
|
||
## 5) Snapshot projections
|
||
|
||
```sql
|
||
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 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
|
||
);
|
||
CREATE UNIQUE INDEX ux_animal_nickname_active
|
||
ON animal_registry(nickname)
|
||
WHERE nickname IS NOT NULL AND status NOT IN ('dead','harvested','sold','merged_into');
|
||
CREATE INDEX idx_animal_registry_loc ON animal_registry(location_id);
|
||
CREATE INDEX idx_animal_registry_filters ON animal_registry(species_code, sex, life_stage, identified);
|
||
CREATE INDEX idx_animal_registry_status ON animal_registry(status);
|
||
CREATE INDEX idx_animal_registry_last_evt ON animal_registry(last_event_utc);
|
||
|
||
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 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 CHECK(json_valid(tags))
|
||
);
|
||
CREATE INDEX idx_roster_loc ON live_animals_by_location(location_id);
|
||
CREATE INDEX idx_roster_filters ON live_animals_by_location(location_id, species_code, sex, life_stage, identified);
|
||
|
||
CREATE TABLE egg_stats_30d_by_location (
|
||
location_id TEXT PRIMARY KEY CHECK(length(location_id)=26) REFERENCES locations(id),
|
||
window_start_utc INTEGER NOT NULL,
|
||
window_end_utc INTEGER NOT NULL,
|
||
eggs_total_pcs INTEGER NOT NULL,
|
||
feed_total_g INTEGER NOT NULL, -- grams, not kg
|
||
feed_layers_g INTEGER NOT NULL, -- grams, not kg
|
||
cost_per_egg_all_eur REAL NOT NULL,
|
||
cost_per_egg_layers_eur REAL NOT NULL,
|
||
layer_eligible_bird_days INTEGER NOT NULL,
|
||
layer_eligible_count_now INTEGER NOT NULL,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
|
||
-- Money: store prices as integer cents everywhere.
|
||
CREATE TABLE feed_inventory (
|
||
feed_type_code TEXT PRIMARY KEY REFERENCES feed_types(code),
|
||
purchased_kg INTEGER NOT NULL DEFAULT 0,
|
||
given_kg INTEGER NOT NULL DEFAULT 0,
|
||
balance_kg INTEGER NOT NULL DEFAULT 0,
|
||
last_purchase_price_per_kg_cents INTEGER, -- integer cents
|
||
last_purchase_at_utc INTEGER,
|
||
last_given_at_utc INTEGER,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
CREATE INDEX idx_feed_inventory_last_on ON feed_inventory(last_purchase_at_utc, last_given_at_utc);
|
||
|
||
CREATE TABLE event_log_by_location (
|
||
event_id TEXT PRIMARY KEY,
|
||
location_id TEXT NOT NULL REFERENCES locations(id),
|
||
ts_utc INTEGER NOT NULL,
|
||
type TEXT NOT NULL,
|
||
actor TEXT NOT NULL,
|
||
summary TEXT NOT NULL CHECK(json_valid(summary))
|
||
);
|
||
CREATE INDEX idx_evlog_loc_ts ON event_log_by_location(location_id, ts_utc DESC);
|
||
CREATE TRIGGER trg_evlog_cap AFTER INSERT ON event_log_by_location
|
||
BEGIN
|
||
DELETE FROM event_log_by_location
|
||
WHERE rowid IN (
|
||
SELECT rowid FROM event_log_by_location
|
||
WHERE location_id=NEW.location_id
|
||
ORDER BY ts_utc DESC
|
||
LIMIT -1 OFFSET 500
|
||
);
|
||
END;
|
||
|
||
CREATE TABLE tag_suggestions (
|
||
tag TEXT PRIMARY KEY,
|
||
total_assignments INTEGER NOT NULL DEFAULT 0,
|
||
active_animals INTEGER NOT NULL DEFAULT 0,
|
||
last_used_utc INTEGER,
|
||
updated_at_utc INTEGER NOT NULL
|
||
);
|
||
|
||
CREATE TABLE user_defaults (
|
||
username TEXT NOT NULL REFERENCES users(username),
|
||
action TEXT NOT NULL CHECK(action IN ('collect_egg','feed_given')),
|
||
location_id TEXT,
|
||
species TEXT,
|
||
animal_filter TEXT,
|
||
feed_type_code TEXT,
|
||
amount_kg INTEGER,
|
||
bag_size_kg INTEGER,
|
||
updated_at_utc INTEGER NOT NULL,
|
||
PRIMARY KEY (username, action)
|
||
);
|
||
|
||
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_animal_aliases_survivor ON animal_aliases(survivor_animal_id);
|
||
```
|
||
|
||
## 6) Events (species-agnostic taxonomy)
|
||
|
||
* `LocationCreated|Renamed|Archived`
|
||
* `AnimalCohortCreated`
|
||
* `AnimalPromoted`
|
||
* `AnimalMoved`
|
||
* `AnimalAttributesUpdated`
|
||
* `AnimalTagged` / `AnimalTagEnded`
|
||
* `HatchRecorded` (creates hatchlings)
|
||
* `AnimalOutcome` (`death|harvest|sold|predator_loss|unknown`, optional yields)
|
||
* `ProductCollected`
|
||
* `ProductSold`
|
||
* `FeedPurchased`
|
||
* `FeedGiven`
|
||
* `EventDeleted` (tombstone)
|
||
* `AnimalMerged`
|
||
* `AnimalStatusCorrected` (admin-only, requires reason)
|
||
|
||
**Event payloads:** validated by Pydantic models (app layer). `events.version` supports upcasters.
|
||
|
||
**Writes to `event_animals`:** `AnimalCohortCreated`, `HatchRecorded`, `AnimalMoved`, `AnimalAttributesUpdated`, `AnimalTagged`, `AnimalTagEnded`, `AnimalOutcome`, `AnimalPromoted`, `AnimalMerged` (survivor+merged), `AnimalStatusCorrected`, `ProductCollected` (each linked animal).
|
||
|
||
**AnimalMerged behavior:** When two animal records are discovered to be the same individual:
|
||
1. User selects merged animal(s) and a survivor animal.
|
||
2. Event records `survivor_animal_id` and `merged_animal_ids[]`.
|
||
3. Merged animals get `status=merged_into`; their events remain on original IDs (historically accurate).
|
||
4. `animal_aliases` table updated: `alias_animal_id→survivor_animal_id`.
|
||
5. Future queries/events resolve aliases via lookup. Animal timeline view shows "Merged from [X] on [date]".
|
||
6. Counts use survivor only; alias table prevents double-counting in roster queries.
|
||
|
||
## 7) Historical state queries (point-in-time)
|
||
|
||
**Resolve filter at `:ts` (template):**
|
||
|
||
```sql
|
||
-- example fields bound: :location_name, :species, :ts, :tag_slug
|
||
WITH roster AS (
|
||
SELECT ali.animal_id
|
||
FROM animal_location_intervals ali
|
||
JOIN locations L ON L.id = ali.location_id
|
||
WHERE L.name = :location_name
|
||
AND ali.start_utc <= :ts
|
||
AND (ali.end_utc IS NULL OR ali.end_utc > :ts)
|
||
),
|
||
sex_at_ts AS (
|
||
SELECT r.animal_id,
|
||
(SELECT value FROM animal_attr_intervals
|
||
WHERE animal_id=r.animal_id AND attr='sex'
|
||
AND start_utc<=:ts AND (end_utc IS NULL OR end_utc>:ts)
|
||
ORDER BY start_utc DESC LIMIT 1) AS sex_val
|
||
FROM roster r
|
||
),
|
||
stage_at_ts AS (
|
||
SELECT r.animal_id,
|
||
(SELECT value FROM animal_attr_intervals
|
||
WHERE animal_id=r.animal_id AND attr='life_stage'
|
||
AND start_utc<=:ts AND (end_utc IS NULL OR end_utc>:ts)
|
||
ORDER BY start_utc DESC LIMIT 1) AS stage_val
|
||
FROM roster r
|
||
),
|
||
status_at_ts AS (
|
||
SELECT r.animal_id,
|
||
(SELECT value FROM animal_attr_intervals
|
||
WHERE animal_id=r.animal_id AND attr='status'
|
||
AND start_utc<=:ts AND (end_utc IS NULL OR end_utc>:ts)
|
||
ORDER BY start_utc DESC LIMIT 1) AS status_val
|
||
FROM roster r
|
||
),
|
||
species_now AS (
|
||
SELECT ar.animal_id, ar.species_code
|
||
FROM animal_registry ar
|
||
WHERE ar.animal_id IN (SELECT animal_id FROM roster)
|
||
),
|
||
tag_match AS (
|
||
SELECT ati.animal_id
|
||
FROM animal_tag_intervals ati
|
||
WHERE ati.tag = :tag_slug
|
||
AND ati.start_utc <= :ts AND (ati.end_utc IS NULL OR ati.end_utc > :ts)
|
||
)
|
||
SELECT r.animal_id
|
||
FROM roster r
|
||
JOIN species_now sp ON sp.animal_id=r.animal_id AND sp.species_code=:species
|
||
JOIN sex_at_ts sx ON sx.animal_id=r.animal_id AND sx.sex_val='female'
|
||
JOIN stage_at_ts st ON st.animal_id=r.animal_id AND st.stage_val='adult'
|
||
JOIN status_at_ts ss ON ss.animal_id=r.animal_id AND ss.status_val='alive'
|
||
JOIN tag_match tm ON tm.animal_id=r.animal_id; -- include only when tag filter used
|
||
```
|
||
|
||
**Roster snapshot at `:ts`:**
|
||
|
||
```sql
|
||
SELECT r.animal_id, sp.species_code,
|
||
(SELECT value FROM animal_attr_intervals WHERE animal_id=r.animal_id AND attr='sex'
|
||
AND start_utc<=:ts AND (end_utc IS NULL OR end_utc>:ts)
|
||
ORDER BY start_utc DESC LIMIT 1) AS sex,
|
||
(SELECT value FROM animal_attr_intervals WHERE animal_id=r.animal_id AND attr='life_stage'
|
||
AND start_utc<=:ts AND (end_utc IS NULL OR end_utc>:ts)
|
||
ORDER BY start_utc DESC LIMIT 1) AS life_stage,
|
||
(SELECT value FROM animal_attr_intervals WHERE animal_id=r.animal_id AND attr='status'
|
||
AND start_utc<=:ts AND (end_utc IS NULL OR end_utc>:ts)
|
||
ORDER BY start_utc DESC LIMIT 1) AS status,
|
||
(SELECT GROUP_CONCAT(tag, ',') FROM animal_tag_intervals
|
||
WHERE animal_id=r.animal_id AND start_utc<=:ts AND (end_utc IS NULL OR end_utc>:ts)) AS active_tags
|
||
FROM animal_location_intervals r
|
||
JOIN locations L ON L.id=r.location_id AND L.name=:location_name
|
||
JOIN animal_registry sp ON sp.animal_id=r.animal_id
|
||
WHERE r.start_utc<=:ts AND (r.end_utc IS NULL OR r.end_utc>:ts);
|
||
```
|
||
|
||
## 8) Concurrency, transactions, consistency
|
||
|
||
* SQLite PRAGMAs on open: `journal_mode=WAL`, `synchronous=FULL`, `foreign_keys=ON`, `busy_timeout=5000`.
|
||
* Each POST: `BEGIN IMMEDIATE` → server resolves selection at `ts_utc` → compute `roster_hash` (xxhash64 of sorted `animal_id`s + from_location when relevant) and `resolved_count` → compare to client. On mismatch: **return diff**; client must resubmit with `confirmed=true`. Then write event, update projections, commit.
|
||
* **Known race (documented):** with **backdated** edits, another txn could change intervals affecting the same `ts_utc` between resolve and commit. We do not re-validate before commit. Eventual consistency is achieved via bounded replay after edits/deletes.
|
||
* Same-animal same-timestamp is rejected (DB unique index).
|
||
* Clock skew guard: reject `ts_utc > now + 5 min`.
|
||
|
||
## 9) Costing and 30-day stats
|
||
|
||
* Window: rolling last 30×24 h.
|
||
* Price at `FeedGiven.ts_utc`: **required** purchase ≤ `ts_utc`. If none → block.
|
||
* Bird-days:
|
||
|
||
* `all_animal_days(location)` = sum of overlap durations of `animal_location_intervals` within window.
|
||
* `layer_eligible_days(location, species)` = as above filtered by `status=alive`, `life_stage=adult`, `sex=female`, `species_code=product species` using `animal_attr_intervals`.
|
||
* Feed proration per `FeedGiven i` at location `L`:
|
||
|
||
```
|
||
share_i = layer_eligible_days(L) / all_animal_days(L)
|
||
feed_layers_g += amount_g_i * share_i
|
||
feed_total_g += amount_g_i
|
||
```
|
||
Note: Feed amounts stored/computed in grams (INTEGER) for precision. Display as kg with 3 decimals.
|
||
* Costs:
|
||
|
||
```
|
||
cost_per_egg_all = (Σ amount_i * price_i) / eggs_total_pcs
|
||
cost_per_egg_layers = (Σ amount_i * price_i * share_i) / eggs_total_pcs
|
||
```
|
||
* Store prices as integer cents; cost/egg stored as REAL; display with 3 decimals. Tests assert with tolerance ±0.001.
|
||
|
||
**Worked example (E2E #1 baseline):**
|
||
```
|
||
Setup: Strip 1 with 10 adult females + 3 adult males (13 total birds).
|
||
Feed purchased: 40 kg @ €1.20/kg.
|
||
|
||
Action: FeedGiven 6 kg, then ProductCollected 12 eggs.
|
||
|
||
Calculation:
|
||
all_animal_days = 13 bird-days (assuming 1 day window for simplicity)
|
||
layer_eligible_days = 10 bird-days (adult females only)
|
||
|
||
share = 10/13 = 0.769230769
|
||
|
||
feed_total_g = 6000 g
|
||
feed_layers_g = 6000 × 0.769230769 = 4615 g (INTEGER truncation)
|
||
|
||
total_feed_cost = 6 kg × €1.20 = €7.20
|
||
layer_feed_cost = €7.20 × 0.769230769 = €5.538
|
||
|
||
cost_per_egg_all = €7.20 / 12 = €0.600
|
||
cost_per_egg_layers = €5.538 / 12 = €0.462
|
||
```
|
||
|
||
## 10) Auth and security
|
||
|
||
* Trust reverse proxy `X-Oidc-Username`. Restrict by `TRUSTED_PROXY_IPS`. Enforce consistent `X-Forwarded-Host/Proto`.
|
||
* CSRF token (cookie + header) on all POSTs + Origin/Referer check.
|
||
* Roles: admin, recorder.
|
||
* **Recorder**: can edit/delete own events only; delete blocked (409) if event has dependents.
|
||
* **Admin**: can edit/delete any event; can cascade delete (tombstone target event + all dependents in single txn).
|
||
|
||
## 11) Selection filter DSL
|
||
|
||
* Fields: `location`, `species`, `sex`, `life_stage`, `identified`, `tag`.
|
||
* AND by default; OR with `|`; negate with `-`; quotes for spaces.
|
||
* Example: `species:duck sex:female life_stage:adult`.
|
||
|
||
## 12) API: routes and forms
|
||
|
||
**GET**
|
||
|
||
* `/` → Egg Quick Capture
|
||
* `/feed` → Feed Quick Capture
|
||
* `/move` → Move Animals
|
||
* `/registry` → Animal Registry (filters, facets, table; infinite scroll 50/page; cursor = base64)
|
||
* `/event-log?location_id=...` → Event Log partial
|
||
|
||
**POST (HTMX)**
|
||
|
||
* `/actions/product-collected`
|
||
Fields: `ts_utc`, `location_id`, `product_code='egg.duck'`, `quantity int≥1`, `notes?`, hidden selection context (`filter`, `resolved_ids[]` server-filled, `roster_hash`, `resolved_count`, `resolver_version='v1'`, `confirmed?`, `nonce`).
|
||
Success: toast + refresh form; keep location; reset qty. 422 on validation; 409 on mismatch → diff panel → confirm resubmit.
|
||
|
||
* `/actions/feed-given`
|
||
Fields: `ts_utc`, `location_id`, `feed_type_code`, `amount_kg int≥1`, `notes?`.
|
||
Defaults: last location, last type at location, amount=default bag size. Block if no purchase ≤ ts_utc.
|
||
|
||
* `/actions/animal-move`
|
||
Fields: `ts_utc`, `to_location_id`, selection context.
|
||
Valid only if all resolved share one `from_location`; block if `to==from`.
|
||
|
||
* `/actions/animal-attrs`
|
||
Fields: `ts_utc`, selection context, `set.sex?`, `set.life_stage?`, `set.repro_status?`.
|
||
|
||
* `/actions/hatch-recorded`
|
||
Fields: `ts_utc`, `species`, `location_id`, `assigned_brood_location_id?`, `hatched_live int≥1`, laid/set windows optional, parent filters optional, `notes?`. Auto-create hatchlings at brood/event location (`life_stage=hatchling`, `sex=unknown`).
|
||
|
||
* `/actions/animal-outcome`
|
||
Fields: `ts_utc`, `outcome ∈ {death,harvest,sold,predator_loss,unknown}`, selection context, `reason?`, `yield_items[]?` lines `{product_code, unit ∈ {piece,kg}, quantity int≥1, weight_kg? (decimal), notes?}`, `notes?`.
|
||
|
||
* `/actions/feed-purchased`
|
||
Fields: `ts_utc`, `feed_type_code`, `bag_size_kg int≥1`, `bags_count int≥1`, `bag_price_cents int≥0`, `vendor?`, `notes?`.
|
||
|
||
* `/actions/product-sold`
|
||
Fields: `ts_utc`, `product_code` (default `egg.duck`), `quantity int≥1`, `total_price_cents int≥0`, `buyer?`, `notes?`. Server stores `unit_price_cents=floor(total/qty)`.
|
||
|
||
* `/actions/animal-cohort`
|
||
Fields: `ts_utc`, `species`, `count int≥1`, `life_stage`, `sex default unknown`, `location_id`, `origin`, optional parent sets + hatch window, `notes?`.
|
||
|
||
* `/actions/animal-promote`
|
||
Fields: `ts_utc`, `animal_id`, `nickname?` (global-unique among active), `sex?`, `repro_status?`, `distinguishing_traits?` (+tags), `parent_sets?`, `notes?`.
|
||
|
||
* `/actions/animal-tag-add` / `/actions/animal-tag-end`
|
||
Fields: `ts_utc`, selection context, `tag`. Add no-ops if already active; end no-ops if not active.
|
||
|
||
* `/actions/animal-status-correct` (admin-only)
|
||
Fields: `ts_utc`, selection context, `new_status ∈ {alive,dead,harvested,sold}`, `reason` (required).
|
||
Use case: fix mistakes (e.g., animal marked dead but found alive). Creates audit trail.
|
||
|
||
**Errors**
|
||
|
||
* 422 validation, 409 mismatch or same-animal same-timestamp conflict, 401/403 auth, 404, 410 gone, 500. Errors return HTML partial with inline messages; toast via `HX-Trigger`.
|
||
|
||
## 13) UI
|
||
|
||
* Framework: FastHTML + HTMX v1.9.x (`head-support, preload, class-tools, loading-states, path-deps, ws`).
|
||
* Components: MonsterUI. Vendored static assets. `/static/vN/...` with immutable cache. HTML `no-store`.
|
||
* Bottom nav: Egg • Feed • Move • Registry.
|
||
* Registry: columns [ID(nickname or anon-ULID4), species, sex, life_stage, location, tags, last event, status]. Facets with counts (species, sex, life_stage, location, tags, status, identified). Infinite scroll, 50/page.
|
||
* Drawer per animal: header summary, timeline (newest first), quick actions.
|
||
|
||
## 14) Projections: apply/revert
|
||
|
||
* Fast-revert only: `FeedGiven`, `FeedPurchased`, `ProductSold` (counter deltas).
|
||
* All interval/snapshot effects (`AnimalMoved`, `AnimalAttributesUpdated`, tags, outcomes, hatch, merges, promotes, status corrections) → **unbounded replay** from earliest affected timestamp:
|
||
|
||
1. Determine earliest affected `ts_utc` (edited/deleted event's timestamp).
|
||
2. Truncate affected projection rows ≥ that timestamp.
|
||
3. Scan events ≥ timestamp by `(ts_utc, id)`, skipping tombstoned; call `apply`.
|
||
4. Log `WARN` if replay processes >1000 events (indicates old event edited; not an error, just visibility).
|
||
* Edits: store pre-edit in `event_revisions`, then `revert(old)` + `apply(new)` inside one txn.
|
||
* Read freshness: `egg_stats_30d_by_location` recomputes on read in a single snapshot txn, then upserts.
|
||
|
||
## 15) Seeds
|
||
|
||
* Users: admin `{ppetru, ines}`, recorder `{guest}`.
|
||
* Locations: `Strip 1..4`, `Nursery 1..4`.
|
||
* Species: `{duck, goose}` active; `{sheep}` inactive.
|
||
* Products (DB): `egg.duck` sellable; duck/goose meat/offal/fat/bones/feathers/down collectable+sellable.
|
||
* Feed types (DB): `starter_zezere_bio_pintos` 20 kg; `grower_zezere_bio_frangos` 20 kg; `layer_zezere_bio_galinhas` 20 kg.
|
||
* Seeder upserts rows. **Idempotent** `LocationCreated` events: append only if none exists for that location.
|
||
|
||
## 16) Migrations
|
||
|
||
* **FastMigrate**. Layout: `migrations/YYYYMMDDHHMM__desc.sql`. CLI wrappers:
|
||
`animaltrack migrate [--to <version>]`, `animaltrack create-migration "desc"`.
|
||
|
||
## 17) Logging, health, metrics
|
||
|
||
* NDJSON lines: `{ts, level, route, actor, ip, method, status, duration_ms, request_id?, event_id?}`. Level `info`. Include `X-Forwarded-For`. Generate `request_id`.
|
||
* `GET /healthz` (DB writable check). Optional `GET /metrics` (env `METRICS_ENABLED`).
|
||
|
||
## 18) Config/env
|
||
|
||
* `PORT`, `DB_PATH`, `AUTH_HEADER_NAME=X-Oidc-Username`, `TRUSTED_PROXY_IPS`, `CSRF_SECRET`, `CSRF_COOKIE_NAME=csrf_token`, `BASE_PATH=/`, `SEED_ON_START=true|false`, `LOG_LEVEL`, `METRICS_ENABLED`.
|
||
* Resolver version in selection context: fixed string `v1`.
|
||
|
||
## 19) Money
|
||
|
||
* EUR. Store all prices as integer cents. Display prices with 2 decimals, cost/egg with 3 decimals.
|
||
|
||
## 20) Tag normalization
|
||
|
||
* ASCII lowercase, trim, spaces→`-`, `[a-z0-9:_-]` only, max 32 chars. Case-insensitive dedupe.
|
||
|
||
## 21) E2E acceptance tests (authoritative)
|
||
|
||
All times UTC. Fresh DB per test. Numeric comparisons on REAL use tolerance `±0.001`.
|
||
|
||
1. **Baseline eggs+feed+costs**
|
||
Seed: Strip 1. Cohort ducks: 10 adult females + 3 adult males @Strip 1. Purchase `layer_zezere_bio_galinhas`: 2×20 kg @ €24 each (price/kg=€1.20).
|
||
Actions: FeedGiven 6 kg @Strip 1. ProductCollected egg.duck 12 @Strip 1.
|
||
Expect:
|
||
|
||
* FeedInventory: purchased_kg=40, given_kg=6, balance_kg=34, last_purchase_price_per_kg_cents=120.
|
||
* EggStats30d(Strip 1): eggs=12; feed_total_g=6000; feed_layers_g=4615; cost_all=0.600±0.001; cost_layers=0.462±0.001.
|
||
|
||
2. **Mixed group proration**
|
||
Add cohort: 10 juvenile ducks @Strip 1.
|
||
Actions: FeedGiven 10 kg. ProductCollected 10 eggs.
|
||
Expect Strip 1: eggs=22; feed_total_g=16000; feed_layers_g=8963; cost_all=0.873±0.001; cost_layers=0.489±0.001.
|
||
|
||
3. **Split flock, per-location stats**
|
||
Move 5 adult females Strip 1→Strip 2.
|
||
Actions: Strip 1 FeedGiven 4 kg; Eggs 5. Strip 2 FeedGiven 3 kg; Eggs 6.
|
||
Expect:
|
||
|
||
* Strip 1: eggs=27; feed_total_g=20000; feed_layers_g=10074; cost_all=0.889±0.001; cost_layers=0.448±0.001.
|
||
* Strip 2: eggs=6; feed_total_g=3000; feed_layers_g=3000; cost_all=0.600±0.001; cost_layers=0.600±0.001.
|
||
* FeedInventory: given_kg=23; balance_kg=17.
|
||
|
||
4. **Backdated eggs use historical roster**
|
||
Backdate ProductCollected 8 eggs before the move in (3).
|
||
Expect Strip 1: eggs=35; feed totals unchanged; cost_all=24/35=0.686±0.001; cost_layers=(12089g×€0.0012/g)/35=0.345±0.001.
|
||
|
||
5. **Edit egg event**
|
||
Edit the backdated 8→6.
|
||
Expect Strip 1: eggs=33; cost_all=24/33=0.727±0.001; cost_layers=(12089g×€0.0012/g)/33=0.366±0.001; `events.version`++ and one row in `event_revisions`.
|
||
|
||
6. **Deletes: recorder vs admin cascade**
|
||
Recorder deletes 4 kg FeedGiven from (3) @Strip 1.
|
||
Expect Strip 1: feed_total_g=16000; feed_layers_g=8963; cost_all=(16×1.20)/33=0.582±0.001; cost_layers=(8963g×€0.0012/g)/33=0.327±0.001.
|
||
FeedInventory: given_kg=19; balance_kg=21.
|
||
Create cohort 1 juvenile @Nursery 4; move to Strip 1. Recorder tries delete cohort → 409 (dependents). Admin deletes cohort with cascade → cohort + move tombstoned; animal removed from registry/roster/intervals.
|
||
|
||
7. **Harvest with yields**
|
||
At Strip 2 select 2 adult females → AnimalOutcome=harvest with yields:
|
||
`meat.part.breast.duck` qty=2 weight_kg=1.4; `fat.rendered.duck` qty=1 weight_kg=0.3.
|
||
Expect: both animals status=harvested; Strip 2 live female count −2; yields present in history/export; EggStats unchanged.
|
||
|
||
8. **Optimistic lock with confirm**
|
||
Pre: after (7), Strip 1 has 5 adult females; Strip 2 has 3.
|
||
Client A resolves filter `species:duck sex:female location:"Strip 1"` (5 ids, `roster_hash=H1`).
|
||
Client B moves 2 of those to Strip 2 (commits).
|
||
Client A submits move to Nursery 1 with `roster_hash=H1`.
|
||
Expect: server 409 diff `{removed:2, added:0}`; UI confirm; A resubmits `confirmed=true`; server re-resolves (3 ids) and moves only those. Final: Strip 1 females=0; Strip 2 females=5; Nursery 1 females=3. Two `AnimalMoved` events logged.
|
||
|
||
## 22) UX defaults
|
||
|
||
* Egg: integer only, min=1, toast + stay, species/location stick, qty clears.
|
||
* Feed: integer kg only, min=1, warn if inventory negative, toast + stay, location/type stick, amount resets to default bag size.
|
||
* Move: default selection=all; valid if one from_location; after submit, nothing sticks.
|
||
|
||
## 23) Seeds and config source
|
||
|
||
* Seeds live in codebase `Seeds` module. Preseed users/locations/species/products/feed types. Append `LocationCreated` **only if** none exists.
|
||
|
||
## 24) Migrations and deploy
|
||
|
||
* FastMigrate. Manual `animaltrack migrate` before serve.
|
||
* Dev: flake.nix + direnv. All dependencies installed by flake from nixpkgs.
|
||
* Deploy: Docker image from same flake. Port and DB path via env. SQLite file path supplied by Nomad.
|
||
|
||
## 25) Backup
|
||
|
||
* Handled outside (operator policy). Note: for WAL backups perform a checkpoint (`wal_checkpoint(TRUNCATE)`) before copying.
|
||
|