Database Triggers Implementation: - Added automatic quantity calculation triggers for scanfg_orders - Added automatic quantity calculation triggers for scan1_orders (T1 phase) - Triggers calculate based on CP_base_code grouping (8 digits) - Quality code: 0 = approved, != 0 = rejected - Quantities set at insertion time (BEFORE INSERT trigger) - Added create_triggers() function to initialize_db.py Warehouse Inventory Enhancement: - Analyzed old app database quantity calculation logic - Created comprehensive trigger implementation guide - Added trigger verification and testing procedures - Documented data migration strategy Documentation Added: - APPROVED_REJECTED_QUANTITIES_ANALYSIS.md - Old app logic analysis - DATABASE_TRIGGERS_IMPLEMENTATION.md - v2 implementation guide - WAREHOUSE_INVENTORY_IMPLEMENTATION.md - Inventory view feature Files Modified: - initialize_db.py: Added create_triggers() function and call in main() - Documentation: 3 comprehensive guides for database and inventory management Quality Metrics: - Triggers maintain legacy compatibility - Automatic calculation ensures data consistency - Performance optimized at database level - Comprehensive testing documented
13 KiB
📊 Approved & Rejected Quantities - Database Trigger Logic
Date: January 30, 2026
Source: Old Application Analysis
Status: ✅ Analysis Complete
Critical for Migration: Yes - This is automatic calculation logic
🎯 Overview
In the original application, approved and rejected quantities are NOT user-entered values. They are automatically calculated and maintained by database triggers that execute whenever a scan record is inserted.
This is a critical distinction for the migration - we need to replicate this logic in the v2 application.
🔑 Key Concepts
Quality Code Values
quality_code = 0 → APPROVED ✅
quality_code = 1+ → REJECTED ❌ (any non-zero value)
What Quantities Track
- approved_quantity: Count of approved scans for this CP_base_code (same CP base, quality_code = 0)
- rejected_quantity: Count of rejected scans for this CP_base_code (same CP base, quality_code != 0)
Important Note
These are counters aggregated by CP_base_code (8 digits), NOT by the full 15-character code!
🗄️ Database Schema (Old App)
scan1_orders & scanfg_orders Tables
CREATE TABLE scan1_orders (
Id INT AUTO_INCREMENT PRIMARY KEY,
operator_code VARCHAR(4) NOT NULL, -- Who scanned (e.g., "OP01")
CP_full_code VARCHAR(15) NOT NULL UNIQUE, -- Full code (e.g., "CP00000001-0001")
OC1_code VARCHAR(4) NOT NULL, -- OC1 code (e.g., "OC01")
OC2_code VARCHAR(4) NOT NULL, -- OC2 code (e.g., "OC02")
CP_base_code VARCHAR(10) GENERATED ALWAYS AS (LEFT(CP_full_code, 10)) STORED, -- Auto-generated from CP_full_code
quality_code INT(3) NOT NULL, -- 0=Approved, 1+=Rejected
date DATE NOT NULL,
time TIME NOT NULL,
approved_quantity INT DEFAULT 0, -- Auto-calculated by trigger
rejected_quantity INT DEFAULT 0 -- Auto-calculated by trigger
);
CREATE TABLE scanfg_orders (
-- Same structure as scan1_orders
Id INT AUTO_INCREMENT PRIMARY KEY,
operator_code VARCHAR(4) NOT NULL,
CP_full_code VARCHAR(15) NOT NULL UNIQUE,
OC1_code VARCHAR(4) NOT NULL,
OC2_code VARCHAR(4) NOT NULL,
CP_base_code VARCHAR(10) GENERATED ALWAYS AS (LEFT(CP_full_code, 10)) STORED,
quality_code INT(3) NOT NULL,
date DATE NOT NULL,
time TIME NOT NULL,
approved_quantity INT DEFAULT 0,
rejected_quantity INT DEFAULT 0
);
Important Detail: CP_base_code
Generated Column: CP_base_code is automatically extracted from the first 10 characters of CP_full_code
This means:
- When you insert:
CP00000001-0001 - Automatically stored:
CP_base_code = CP00000001 - Used in trigger: for grouping and counting
🔄 Trigger Logic (Old App)
Trigger: set_quantities_scan1 (for scan1_orders)
Executes BEFORE INSERT on each new row:
CREATE TRIGGER set_quantities_scan1
BEFORE INSERT ON scan1_orders
FOR EACH ROW
BEGIN
-- Step 1: Count how many APPROVED entries already exist for this CP_base_code
SET @approved = (SELECT COUNT(*) FROM scan1_orders
WHERE CP_base_code = LEFT(NEW.CP_full_code, 10)
AND quality_code = 0);
-- Step 2: Count how many REJECTED entries already exist for this CP_base_code
SET @rejected = (SELECT COUNT(*) FROM scan1_orders
WHERE CP_base_code = LEFT(NEW.CP_full_code, 10)
AND quality_code != 0);
-- Step 3: Add 1 to appropriate counter based on this new row's quality_code
IF NEW.quality_code = 0 THEN
-- This is an APPROVED scan
SET NEW.approved_quantity = @approved + 1;
SET NEW.rejected_quantity = @rejected;
ELSE
-- This is a REJECTED scan
SET NEW.approved_quantity = @approved;
SET NEW.rejected_quantity = @rejected + 1;
END IF;
END;
Trigger: set_quantities_fg (for scanfg_orders)
Identical logic as set_quantities_scan1 but for scanfg_orders table:
CREATE TRIGGER set_quantities_fg
BEFORE INSERT ON scanfg_orders
FOR EACH ROW
BEGIN
-- Count existing approved for this CP_base_code
SET @approved = (SELECT COUNT(*) FROM scanfg_orders
WHERE CP_base_code = LEFT(NEW.CP_full_code, 10)
AND quality_code = 0);
-- Count existing rejected for this CP_base_code
SET @rejected = (SELECT COUNT(*) FROM scanfg_orders
WHERE CP_base_code = LEFT(NEW.CP_full_code, 10)
AND quality_code != 0);
-- Add 1 to appropriate counter for this new row
IF NEW.quality_code = 0 THEN
SET NEW.approved_quantity = @approved + 1;
SET NEW.rejected_quantity = @rejected;
ELSE
SET NEW.approved_quantity = @approved;
SET NEW.rejected_quantity = @rejected + 1;
END IF;
END;
📊 Example Walkthrough
Scenario: Scanning CP00000001 with Different Quality Codes
Initial State
scanfg_orders table is empty
Scan 1: CP00000001-0001, quality_code = 0 (APPROVED)
BEFORE INSERT trigger executes:
@approved = COUNT(*) WHERE CP_base_code = "CP00000001" AND quality_code = 0
= 0 (no existing records)
@rejected = COUNT(*) WHERE CP_base_code = "CP00000001" AND quality_code != 0
= 0 (no existing records)
NEW.quality_code = 0 (APPROVED)
→ Set NEW.approved_quantity = 0 + 1 = 1
→ Set NEW.rejected_quantity = 0
Record inserted:
Id | operator_code | CP_full_code | quality_code | approved_qty | rejected_qty
1 | OP01 | CP00000001-0001 | 0 | 1 | 0
Scan 2: CP00000001-0002, quality_code = 0 (APPROVED)
BEFORE INSERT trigger executes:
@approved = COUNT(*) WHERE CP_base_code = "CP00000001" AND quality_code = 0
= 1 (found Scan 1)
@rejected = COUNT(*) WHERE CP_base_code = "CP00000001" AND quality_code != 0
= 0
NEW.quality_code = 0 (APPROVED)
→ Set NEW.approved_quantity = 1 + 1 = 2
→ Set NEW.rejected_quantity = 0
Record inserted:
Id | operator_code | CP_full_code | quality_code | approved_qty | rejected_qty
2 | OP02 | CP00000001-0002 | 0 | 2 | 0
Scan 3: CP00000001-0003, quality_code = 2 (REJECTED)
BEFORE INSERT trigger executes:
@approved = COUNT(*) WHERE CP_base_code = "CP00000001" AND quality_code = 0
= 2 (found Scans 1 & 2)
@rejected = COUNT(*) WHERE CP_base_code = "CP00000001" AND quality_code != 0
= 0
NEW.quality_code = 2 (REJECTED, non-zero)
→ Set NEW.approved_quantity = 2
→ Set NEW.rejected_quantity = 0 + 1 = 1
Record inserted:
Id | operator_code | CP_full_code | quality_code | approved_qty | rejected_qty
3 | OP01 | CP00000001-0003 | 2 | 2 | 1
Scan 4: CP00000002-0001, quality_code = 0 (APPROVED)
BEFORE INSERT trigger executes:
@approved = COUNT(*) WHERE CP_base_code = "CP00000002" AND quality_code = 0
= 0 (different CP base code!)
@rejected = COUNT(*) WHERE CP_base_code = "CP00000002" AND quality_code != 0
= 0
NEW.quality_code = 0 (APPROVED)
→ Set NEW.approved_quantity = 0 + 1 = 1
→ Set NEW.rejected_quantity = 0
Record inserted:
Id | operator_code | CP_full_code | quality_code | approved_qty | rejected_qty
4 | OP03 | CP00000002-0001 | 0 | 1 | 0
Final Table State
CP00000001 group:
CP00000001-0001 (Approved, 0) → approved_qty=1, rejected_qty=0
CP00000001-0002 (Approved, 0) → approved_qty=2, rejected_qty=0
CP00000001-0003 (Rejected, 2) → approved_qty=2, rejected_qty=1
CP00000002 group:
CP00000002-0001 (Approved, 0) → approved_qty=1, rejected_qty=0
🔑 Critical Points
1. Aggregation by CP_base_code (8 digits)
Each record shows:
- How many approved scans exist for its CP base code
- How many rejected scans exist for its CP base code
It's NOT the count of just that specific full code!
2. Trigger Runs on INSERT ONLY
- Quantities are set when record is inserted
- They are NOT updated if other records are inserted later
- Each record's quantities represent the state AT THE TIME OF INSERTION
3. Example Impact
If you insert records in different order, quantities will differ:
Order 1: Insert Approved, then Rejected
Approved record: approved_qty=1, rejected_qty=0
Rejected record: approved_qty=1, rejected_qty=1 ← Includes the approved!
Order 2: Insert Rejected, then Approved
Rejected record: approved_qty=0, rejected_qty=1
Approved record: approved_qty=1, rejected_qty=1 ← Updated count
4. Quality Code Interpretation
quality_code = 0→ Approved ✅quality_code != 0→ Rejected ❌ (could be 1, 2, 3, etc.)
The trigger counts ANY non-zero value as rejected.
🚀 Migration Approach
Option 1: Use Database Triggers (Recommended)
Pros:
- Exact replica of old system behavior
- Automatic calculation
- Consistent with legacy data
- Performance optimized at DB level
Cons:
- Complex trigger logic
- Hard to debug
- Must match old behavior exactly
Option 2: Calculate in Python
Pros:
- Easy to understand and debug
- Flexible logic
- Can add validation
Cons:
- Performance impact for high volume
- Must call calculation function on every insert
- Must ensure consistency
Option 3: Store Pre-calculated Values (Batch)
Pros:
- Can cache results
- Fast queries
- Good for reporting
Cons:
- Data can become stale
- Requires batch update process
- Extra complexity
📋 Implementation Steps for v2
Step 1: Create Generated Column
ALTER TABLE scanfg_orders ADD COLUMN
cp_base_code VARCHAR(10) GENERATED ALWAYS AS (SUBSTRING(CP_full_code, 1, 10)) STORED;
Step 2: Create Trigger
Copy the set_quantities_fg trigger from old app, adjusted for new table structure
Step 3: Test
Insert test records and verify quantities calculate correctly
Step 4: Update Routes
Update FG Scan route to use quality_code properly:
- User selects "Approved" or "Rejected"
- System sets quality_code = 0 (approved) or quality_code = 1 (rejected)
- Trigger automatically sets quantities
🔍 Current v2 Status
What We Have Now
- scanfg_orders table with box_id and location_id
- Manual quantity input (NOT automatic!)
What We Need to Add
- quality_code field interpretation (0 vs 1+)
- Database triggers for automatic calculation
- Update FG Scan form to capture quality status properly
- Remove manual quantity entry from forms
📝 Database Differences: Old vs New
| Aspect | Old App | New v2 | Notes |
|---|---|---|---|
| CP_base_code | GENERATED ALWAYS | Manual? | Should also be GENERATED |
| Quantities | AUTO (trigger) | Manual | NEEDS UPDATE |
| Quality Code | 0/1+ system | Storing in DB | GOOD |
| Trigger Logic | Complex | N/A yet | Needs implementation |
| Multiple Suffixes | Yes (-0001, -0002) | Yes | Same structure |
🎯 Recommendation
Implement database triggers to automatically calculate approved/rejected quantities. This ensures:
- ✅ Consistency with legacy data
- ✅ Automatic calculation (no user entry needed)
- ✅ Data integrity at database level
- ✅ Performance (calculated once on insert)
- ✅ Easy to audit (SQL-based logic)
📚 Related Tables
Dependencies
- scanfg_orders ← Contains quality_code
- scan1_orders ← T1 phase (has same trigger)
- boxes_crates ← FK relationship
- warehouse_locations ← FK relationship
Query Examples
Get all scans with their aggregated quantities:
SELECT
CP_full_code,
SUBSTRING(CP_full_code, 1, 10) as cp_base,
operator_code,
quality_code,
approved_quantity,
rejected_quantity,
date,
time
FROM scanfg_orders
ORDER BY created_at DESC;
Verify trigger working correctly:
-- All scans for CP base "CP00000001"
SELECT
CP_full_code,
quality_code,
approved_quantity,
rejected_quantity
FROM scanfg_orders
WHERE SUBSTRING(CP_full_code, 1, 10) = 'CP00000001'
ORDER BY created_at;
-- Should show:
-- - All rows with same approved_qty and rejected_qty for same CP_base
-- - Each new scan increments quantities correctly
✅ Checklist for v2 Implementation
- Add cp_base_code as GENERATED ALWAYS column
- Create set_quantities_fg trigger in v2
- Test trigger with sample inserts
- Update FG Scan form to capture quality status
- Update routes.py to set quality_code properly
- Remove manual quantity entry from frontend
- Verify migration data (recalculate quantities for existing records)
- Create documentation for team
- Test bulk imports
📞 Migration Notes
When migrating existing data from old app:
- Old app quantities are CALCULATED and IMMUTABLE (set at insert time)
- V2 should use same trigger logic
- Existing records need trigger applied during migration
- Test thoroughly with production data sample
Status: ✅ Analysis Complete
Next Step: Implement triggers in v2 application
Priority: HIGH - Affects data accuracy and reports