Files
usda-vision/management-dashboard-web-app/NEW_DATABASE_SCHEMA.md
salirezav aaeb164a32 Refactor experiment management and update data structures
- Renamed columns in the experimental run sheet CSV for clarity.
- Updated the ExperimentForm component to include new fields for weight per repetition and additional parameters specific to Meyer Cracker experiments.
- Enhanced the data entry logic to handle new experiment phases and machine types.
- Refactored repetition scheduling logic to use scheduled_date instead of schedule_status for better clarity in status representation.
- Improved the user interface for displaying experiment phases and their associated statuses.
- Removed outdated seed data and updated database migration scripts to reflect the new schema changes.
2025-09-24 14:27:28 -04:00

511 lines
16 KiB
Markdown

# New Database Schema Documentation
## Overview
The database has been restructured to support a more flexible experiment phase system. Each experiment can now have different combinations of phases (soaking, airdrying, cracking, shelling), and each phase has its own parameters stored in separate tables.
## Key Changes
### 1. Experiment Phases Table
The `experiment_phases` table now includes boolean flags to indicate which phases are enabled:
```sql
CREATE TABLE public.experiment_phases (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL UNIQUE,
description TEXT,
has_soaking BOOLEAN NOT NULL DEFAULT false,
has_airdrying BOOLEAN NOT NULL DEFAULT false,
has_cracking BOOLEAN NOT NULL DEFAULT false,
has_shelling BOOLEAN NOT NULL DEFAULT false,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id)
);
```
**Constraint**: At least one phase must be selected (`has_soaking = true OR has_airdrying = true OR has_cracking = true OR has_shelling = true`).
### 2. Machine Types Table
New table to support different cracking machines:
```sql
CREATE TABLE public.machine_types (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL UNIQUE,
description TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id)
);
```
**Default machine types**:
- JC Cracker
- Meyer Cracker
### 3. Phase-Specific Tables
#### Soaking Table
```sql
CREATE TABLE public.soaking (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL,
actual_start_time TIMESTAMP WITH TIME ZONE,
soaking_duration_minutes INTEGER NOT NULL CHECK (soaking_duration_minutes > 0),
scheduled_end_time TIMESTAMP WITH TIME ZONE NOT NULL,
actual_end_time TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id)
);
```
**Features**:
- `scheduled_end_time` is automatically calculated from `scheduled_start_time + soaking_duration_minutes`
- Can be associated with either an experiment (template) or a specific repetition
#### Airdrying Table
```sql
CREATE TABLE public.airdrying (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL,
actual_start_time TIMESTAMP WITH TIME ZONE,
duration_minutes INTEGER NOT NULL CHECK (duration_minutes > 0),
scheduled_end_time TIMESTAMP WITH TIME ZONE NOT NULL,
actual_end_time TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id)
);
```
**Features**:
- `scheduled_start_time` is automatically set to the soaking's `scheduled_end_time` if not provided
- `scheduled_end_time` is automatically calculated from `scheduled_start_time + duration_minutes`
#### Cracking Table
```sql
CREATE TABLE public.cracking (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
machine_type_id UUID NOT NULL REFERENCES public.machine_types(id),
scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL,
actual_start_time TIMESTAMP WITH TIME ZONE,
actual_end_time TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id)
);
```
**Features**:
- `scheduled_start_time` is automatically set to the airdrying's `scheduled_end_time` if not provided
- No duration or scheduled end time (user sets actual end time)
- Requires selection of machine type
#### Shelling Table
```sql
CREATE TABLE public.shelling (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_id UUID NOT NULL REFERENCES public.experiments(id) ON DELETE CASCADE,
repetition_id UUID REFERENCES public.experiment_repetitions(id) ON DELETE CASCADE,
scheduled_start_time TIMESTAMP WITH TIME ZONE NOT NULL,
actual_start_time TIMESTAMP WITH TIME ZONE,
actual_end_time TIMESTAMP WITH TIME ZONE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id)
);
```
### 4. Machine-Specific Parameter Tables
#### JC Cracker Parameters
```sql
CREATE TABLE public.jc_cracker_parameters (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
cracking_id UUID NOT NULL REFERENCES public.cracking(id) ON DELETE CASCADE,
plate_contact_frequency_hz DOUBLE PRECISION NOT NULL CHECK (plate_contact_frequency_hz > 0),
throughput_rate_pecans_sec DOUBLE PRECISION NOT NULL CHECK (throughput_rate_pecans_sec > 0),
crush_amount_in DOUBLE PRECISION NOT NULL CHECK (crush_amount_in >= 0),
entry_exit_height_diff_in DOUBLE PRECISION NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
```
#### Meyer Cracker Parameters
```sql
CREATE TABLE public.meyer_cracker_parameters (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
cracking_id UUID NOT NULL REFERENCES public.cracking(id) ON DELETE CASCADE,
motor_speed_hz DOUBLE PRECISION NOT NULL CHECK (motor_speed_hz > 0),
jig_displacement_inches DOUBLE PRECISION NOT NULL CHECK (jig_displacement_inches >= 0),
spring_stiffness_nm DOUBLE PRECISION NOT NULL CHECK (spring_stiffness_nm > 0),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
```
### 5. Updated Experiments Table
```sql
CREATE TABLE public.experiments (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
experiment_number INTEGER UNIQUE NOT NULL,
reps_required INTEGER NOT NULL CHECK (reps_required > 0),
weight_per_repetition_lbs DOUBLE PRECISION NOT NULL DEFAULT 0 CHECK (weight_per_repetition_lbs > 0),
results_status TEXT NOT NULL DEFAULT 'valid' CHECK (results_status IN ('valid', 'invalid')),
completion_status BOOLEAN NOT NULL DEFAULT false,
phase_id UUID REFERENCES public.experiment_phases(id) ON DELETE SET NULL,
soaking_id UUID REFERENCES public.soaking(id) ON DELETE SET NULL,
airdrying_id UUID REFERENCES public.airdrying(id) ON DELETE SET NULL,
cracking_id UUID REFERENCES public.cracking(id) ON DELETE SET NULL,
shelling_id UUID REFERENCES public.shelling(id) ON DELETE SET NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by UUID NOT NULL REFERENCES public.user_profiles(id)
);
```
**Changes**:
- Added `weight_per_repetition_lbs` field
- Added foreign key references to phase tables
- Removed phase-specific parameters (moved to phase tables)
## Database Views
### experiments_with_phases
A comprehensive view that joins experiments with all their phase information:
```sql
CREATE VIEW public.experiments_with_phases AS
SELECT
e.*,
ep.name as phase_name,
ep.description as phase_description,
ep.has_soaking,
ep.has_airdrying,
ep.has_cracking,
ep.has_shelling,
s.id as soaking_id,
s.scheduled_start_time as soaking_scheduled_start,
s.actual_start_time as soaking_actual_start,
s.soaking_duration_minutes,
s.scheduled_end_time as soaking_scheduled_end,
s.actual_end_time as soaking_actual_end,
ad.id as airdrying_id,
ad.scheduled_start_time as airdrying_scheduled_start,
ad.actual_start_time as airdrying_actual_start,
ad.duration_minutes as airdrying_duration,
ad.scheduled_end_time as airdrying_scheduled_end,
ad.actual_end_time as airdrying_actual_end,
c.id as cracking_id,
c.scheduled_start_time as cracking_scheduled_start,
c.actual_start_time as cracking_actual_start,
c.actual_end_time as cracking_actual_end,
mt.name as machine_type_name,
sh.id as shelling_id,
sh.scheduled_start_time as shelling_scheduled_start,
sh.actual_start_time as shelling_actual_start,
sh.actual_end_time as shelling_actual_end
FROM public.experiments e
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
LEFT JOIN public.soaking s ON e.soaking_id = s.id
LEFT JOIN public.airdrying ad ON e.airdrying_id = ad.id
LEFT JOIN public.cracking c ON e.cracking_id = c.id
LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id
LEFT JOIN public.shelling sh ON e.shelling_id = sh.id;
```
### repetitions_with_phases
A view for repetitions with their phase information:
```sql
CREATE VIEW public.repetitions_with_phases AS
SELECT
er.*,
e.experiment_number,
e.weight_per_repetition_lbs,
ep.name as phase_name,
ep.has_soaking,
ep.has_airdrying,
ep.has_cracking,
ep.has_shelling,
-- ... (similar phase fields as above)
FROM public.experiment_repetitions er
JOIN public.experiments e ON er.experiment_id = e.id
LEFT JOIN public.experiment_phases ep ON e.phase_id = ep.id
LEFT JOIN public.soaking s ON er.id = s.repetition_id
LEFT JOIN public.airdrying ad ON er.id = ad.repetition_id
LEFT JOIN public.cracking c ON er.id = c.repetition_id
LEFT JOIN public.machine_types mt ON c.machine_type_id = mt.id
LEFT JOIN public.shelling sh ON er.id = sh.repetition_id;
```
## TypeScript Interfaces
### New Interfaces Added
```typescript
// Machine Types
export interface MachineType {
id: string
name: string
description?: string | null
created_at: string
updated_at: string
created_by: string
}
// Phase-specific interfaces
export interface Soaking {
id: string
experiment_id: string
repetition_id?: string | null
scheduled_start_time: string
actual_start_time?: string | null
soaking_duration_minutes: number
scheduled_end_time: string
actual_end_time?: string | null
created_at: string
updated_at: string
created_by: string
}
export interface Airdrying {
id: string
experiment_id: string
repetition_id?: string | null
scheduled_start_time: string
actual_start_time?: string | null
duration_minutes: number
scheduled_end_time: string
actual_end_time?: string | null
created_at: string
updated_at: string
created_by: string
}
export interface Cracking {
id: string
experiment_id: string
repetition_id?: string | null
machine_type_id: string
scheduled_start_time: string
actual_start_time?: string | null
actual_end_time?: string | null
created_at: string
updated_at: string
created_by: string
}
export interface Shelling {
id: string
experiment_id: string
repetition_id?: string | null
scheduled_start_time: string
actual_start_time?: string | null
actual_end_time?: string | null
created_at: string
updated_at: string
created_by: string
}
// Machine-specific parameter interfaces
export interface JCCrackerParameters {
id: string
cracking_id: string
plate_contact_frequency_hz: number
throughput_rate_pecans_sec: number
crush_amount_in: number
entry_exit_height_diff_in: number
created_at: string
updated_at: string
}
export interface MeyerCrackerParameters {
id: string
cracking_id: string
motor_speed_hz: number
jig_displacement_inches: number
spring_stiffness_nm: number
created_at: string
updated_at: string
}
```
### Updated Interfaces
```typescript
export interface ExperimentPhase {
id: string
name: string
description?: string | null
has_soaking: boolean
has_airdrying: boolean
has_cracking: boolean
has_shelling: boolean
created_at: string
updated_at: string
created_by: string
}
export interface Experiment {
id: string
experiment_number: number
reps_required: number
weight_per_repetition_lbs: number
results_status: ResultsStatus
completion_status: boolean
phase_id?: string | null
soaking_id?: string | null
airdrying_id?: string | null
cracking_id?: string | null
shelling_id?: string | null
created_at: string
updated_at: string
created_by: string
}
```
## API Management Functions
### New Management Objects
1. **machineTypeManagement**: Functions to manage machine types
2. **phaseManagement**: Functions to manage all phase-specific data
3. **machineParameterManagement**: Functions to manage machine-specific parameters
### Key Functions
```typescript
// Machine Type Management
machineTypeManagement.getAllMachineTypes()
machineTypeManagement.getMachineTypeById(id)
// Phase Management
phaseManagement.createSoaking(request)
phaseManagement.createAirdrying(request)
phaseManagement.createCracking(request)
phaseManagement.createShelling(request)
// Machine Parameter Management
machineParameterManagement.createJCCrackerParameters(request)
machineParameterManagement.createMeyerCrackerParameters(request)
```
## Usage Examples
### Creating an Experiment with Phases
1. **Create Experiment Phase Definition**:
```typescript
const phaseData = {
name: "Full Process Experiment",
description: "Complete pecan processing with all phases",
has_soaking: true,
has_airdrying: true,
has_cracking: true,
has_shelling: true
};
const phase = await experimentPhaseManagement.createExperimentPhase(phaseData);
```
2. **Create Experiment**:
```typescript
const experimentData = {
experiment_number: 1001,
reps_required: 3,
weight_per_repetition_lbs: 50.0,
phase_id: phase.id
};
const experiment = await experimentManagement.createExperiment(experimentData);
```
3. **Create Phase Data** (if phases are enabled):
```typescript
// Soaking
const soakingData = {
experiment_id: experiment.id,
scheduled_start_time: "2025-01-15T08:00:00Z",
soaking_duration_minutes: 120
};
const soaking = await phaseManagement.createSoaking(soakingData);
// Airdrying (scheduled start will be auto-calculated from soaking end)
const airdryingData = {
experiment_id: experiment.id,
duration_minutes: 180
};
const airdrying = await phaseManagement.createAirdrying(airdryingData);
// Cracking
const crackingData = {
experiment_id: experiment.id,
machine_type_id: "jc-cracker-id", // or meyer-cracker-id
// scheduled start will be auto-calculated from airdrying end
};
const cracking = await phaseManagement.createCracking(crackingData);
// Add machine-specific parameters
const jcParams = {
cracking_id: cracking.id,
plate_contact_frequency_hz: 60.0,
throughput_rate_pecans_sec: 2.5,
crush_amount_in: 0.25,
entry_exit_height_diff_in: 0.5
};
await machineParameterManagement.createJCCrackerParameters(jcParams);
```
4. **Update Experiment with Phase References**:
```typescript
await experimentManagement.updateExperiment(experiment.id, {
soaking_id: soaking.id,
airdrying_id: airdrying.id,
cracking_id: cracking.id
});
```
### Creating Repetitions with Phase Data
When creating repetitions, you can create phase-specific data for each repetition:
```typescript
// Create repetition
const repetition = await repetitionManagement.createRepetition({
experiment_id: experiment.id,
repetition_number: 1
});
// Create phase data for this specific repetition
const repetitionSoaking = await phaseManagement.createSoaking({
experiment_id: experiment.id,
repetition_id: repetition.id,
scheduled_start_time: "2025-01-15T08:00:00Z",
soaking_duration_minutes: 120
});
```
## Migration Notes
- The old phase-specific parameters in the `experiments` table are preserved for backward compatibility
- New experiments should use the new phase-specific tables
- The existing draft system continues to work with the new schema
- All RLS policies are properly configured for the new tables
## Benefits of New Schema
1. **Flexibility**: Each experiment can have different combinations of phases
2. **Machine Support**: Easy to add new machine types with different parameters
3. **Separation of Concerns**: Phase parameters are stored in dedicated tables
4. **Automatic Calculations**: Scheduled times are automatically calculated based on phase dependencies
5. **Scalability**: Easy to add new phases or modify existing ones
6. **Data Integrity**: Strong constraints ensure data consistency