diff --git a/.gitignore b/.gitignore index 5f4bb63..78d872d 100644 --- a/.gitignore +++ b/.gitignore @@ -156,6 +156,7 @@ dist/ # PostgreSQL *.sql !init-db.sql +!*_migration.sql # Database dumps *.dump diff --git a/2025-05-30 temporal_migration.sql b/2025-05-30 temporal_migration.sql new file mode 100644 index 0000000..13fb353 --- /dev/null +++ b/2025-05-30 temporal_migration.sql @@ -0,0 +1,122 @@ +-- Migration script for adding temporal tables to products +-- Run this script to add versioning support to your existing database +-- +-- Note: We use '9999-12-31' as the "far future" date to represent +-- the current/active version of a product. This is more portable than PostgreSQL's +-- 'infinity' and works well with both PostgreSQL and SQLite. +-- +-- New products will use CURRENT_DATE as valid_from, but existing products +-- are set to '2025-05-01' as a baseline date for historical tracking. + +BEGIN; + +-- Step 1: Add temporal columns to existing products table +ALTER TABLE products +ADD COLUMN valid_from DATE DEFAULT CURRENT_DATE NOT NULL, +ADD COLUMN valid_to DATE DEFAULT '9999-12-31' NOT NULL, +ADD COLUMN deleted BOOLEAN DEFAULT FALSE NOT NULL; + +-- Step 2: Create products_history table +CREATE TABLE products_history ( + history_id SERIAL PRIMARY KEY, + id INTEGER NOT NULL, + name VARCHAR NOT NULL, + category_id INTEGER NOT NULL, + brand_id INTEGER, + organic BOOLEAN DEFAULT FALSE, + weight FLOAT, + weight_unit VARCHAR DEFAULT 'piece', + created_at TIMESTAMPTZ, + updated_at TIMESTAMPTZ, + valid_from DATE NOT NULL, + valid_to DATE NOT NULL, + deleted BOOLEAN DEFAULT FALSE NOT NULL, + operation CHAR(1) NOT NULL, + archived_at TIMESTAMPTZ DEFAULT NOW() NOT NULL +); + +-- Step 3: Create indexes for performance +CREATE INDEX idx_products_history_id ON products_history(id); +CREATE INDEX idx_products_history_valid_period ON products_history(id, valid_from, valid_to); +CREATE INDEX idx_products_valid_period ON products(id, valid_from, valid_to); + +-- Step 4: Create trigger function for automatic versioning +CREATE OR REPLACE FUNCTION products_versioning_trigger() +RETURNS TRIGGER AS $$ +BEGIN + -- Handle DELETE operations + IF TG_OP = 'DELETE' THEN + -- Create history record for the deleted product + INSERT INTO products_history ( + id, name, category_id, brand_id, organic, weight, weight_unit, + created_at, updated_at, valid_from, valid_to, deleted, operation + ) VALUES ( + OLD.id, OLD.name, OLD.category_id, OLD.brand_id, OLD.organic, + OLD.weight, OLD.weight_unit, OLD.created_at, OLD.updated_at, + OLD.valid_from, CURRENT_DATE, OLD.deleted, 'D' + ); + + RETURN OLD; + END IF; + + -- Handle UPDATE operations + IF TG_OP = 'UPDATE' THEN + -- Check if any versioned fields have changed + IF (OLD.name IS DISTINCT FROM NEW.name OR + OLD.category_id IS DISTINCT FROM NEW.category_id OR + OLD.brand_id IS DISTINCT FROM NEW.brand_id OR + OLD.organic IS DISTINCT FROM NEW.organic OR + OLD.weight IS DISTINCT FROM NEW.weight OR + OLD.weight_unit IS DISTINCT FROM NEW.weight_unit OR + OLD.deleted IS DISTINCT FROM NEW.deleted) THEN + + -- Determine the valid_to date for the history record + DECLARE + history_valid_to DATE; + BEGIN + -- If valid_from was manually changed, use that as the cutoff + -- Otherwise, use current date for automatic versioning + IF OLD.valid_from IS DISTINCT FROM NEW.valid_from THEN + history_valid_to = NEW.valid_from; + ELSE + history_valid_to = CURRENT_DATE; + -- For automatic versioning, update the valid_from to today + NEW.valid_from = CURRENT_DATE; + END IF; + + -- Create history record with the old data + INSERT INTO products_history ( + id, name, category_id, brand_id, organic, weight, weight_unit, + created_at, updated_at, valid_from, valid_to, deleted, operation + ) VALUES ( + OLD.id, OLD.name, OLD.category_id, OLD.brand_id, OLD.organic, + OLD.weight, OLD.weight_unit, OLD.created_at, OLD.updated_at, + OLD.valid_from, history_valid_to, OLD.deleted, 'U' + ); + END; + + -- Always ensure valid_to is set to far future for current version + NEW.valid_to = '9999-12-31'; + NEW.updated_at = NOW(); + END IF; + + RETURN NEW; + END IF; + + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +-- Step 5: Create the trigger +CREATE TRIGGER products_versioning_trigger + BEFORE UPDATE OR DELETE ON products + FOR EACH ROW + EXECUTE FUNCTION products_versioning_trigger(); + +-- Step 6: Initialize existing products with proper temporal data +UPDATE products +SET valid_from = '2025-05-01', + valid_to = '9999-12-31' +WHERE valid_from IS NULL OR valid_to IS NULL; + +COMMIT; \ No newline at end of file diff --git a/SOFT_DELETE_IMPLEMENTATION.md b/SOFT_DELETE_IMPLEMENTATION.md new file mode 100644 index 0000000..6e73590 --- /dev/null +++ b/SOFT_DELETE_IMPLEMENTATION.md @@ -0,0 +1,271 @@ +# Soft Delete Implementation with Historical Tracking + +## Overview + +This implementation extends the existing temporal tables system to support soft deletes with proper historical tracking. When a product is "deleted", it's not actually removed from the database but marked as deleted with a timestamp, while maintaining full historical data. + +## Key Features + +### 1. Soft Delete Mechanism +- Products are marked as `deleted = true` instead of being physically removed +- Deletion creates a historical record of the product's state before deletion +- Deleted products get a new `valid_from` date set to the deletion date +- All historical versions remain intact for audit purposes + +### 2. UI Enhancements +- **Product List**: "Show deleted" toggle next to "Add New Product" button +- **Visual Indicators**: Deleted products shown with: + - Red background tint and reduced opacity + - Strikethrough text + - 🗑️ emoji indicator + - Disabled edit/duplicate/delete actions +- **Shopping Events**: Products deleted before/on shopping date are automatically filtered out + +### 3. API Behavior +- **Default**: Deleted products are hidden from all product listings +- **Optional**: `show_deleted=true` parameter shows all products including deleted ones +- **Shopping Events**: New endpoint `/products/available-for-shopping/{date}` filters products based on deletion status at specific date + +## Database Schema Changes + +### Products Table +```sql +ALTER TABLE products +ADD COLUMN deleted BOOLEAN DEFAULT FALSE NOT NULL; +``` + +### Products History Table +```sql +-- Already included in products_history table +deleted BOOLEAN DEFAULT FALSE NOT NULL +``` + +### Updated Trigger +The `products_versioning_trigger` now **consistently handles ALL historization**: +- **UPDATE operations**: Creates history records for both automatic and manual versioning +- **DELETE operations**: Creates history records when products are deleted +- **Smart versioning**: Automatically detects manual vs automatic versioning based on `valid_from` changes +- **Centralized logic**: All temporal logic is in the database trigger, not split between trigger and application + +### Trigger Benefits +1. **Consistency**: All versioning operations follow the same pattern +2. **Reliability**: Database-level enforcement prevents inconsistencies +3. **Simplicity**: Application code just sets fields, trigger handles the rest +4. **Performance**: Single database operation handles both data update and history creation + +## API Endpoints + +### Modified Endpoints + +#### `GET /products/` +- **New Parameter**: `show_deleted: bool = False` +- **Behavior**: Filters out deleted products by default +- **Usage**: `GET /products/?show_deleted=true` to include deleted products + +#### `PUT /products/{id}` & `DELETE /products/{id}` +- **Enhanced**: Now properly handles soft delete with historical tracking +- **Validation**: Prevents operations on already-deleted products + +### New Endpoints + +#### `GET /products/available-for-shopping/{shopping_date}` +- **Purpose**: Get products that were available (not deleted) on a specific shopping date +- **Logic**: Returns products where: + - `deleted = false` (never deleted), OR + - `deleted = true` AND `valid_from > shopping_date` (deleted after shopping date) +- **Usage**: Used by shopping event modals to filter product lists + +## Frontend Implementation + +### ProductList Component +```typescript +// New state for toggle +const [showDeleted, setShowDeleted] = useState(false); + +// Updated API call +const response = await productApi.getAll(showDeleted); + +// Visual styling for deleted products +className={`hover:bg-gray-50 ${product.deleted ? 'bg-red-50 opacity-75' : ''}`} +``` + +### AddShoppingEventModal Component +```typescript +// Dynamic product fetching based on shopping date +const response = formData.date + ? await productApi.getAvailableForShopping(formData.date) + : await productApi.getAll(false); + +// Refetch products when date changes +useEffect(() => { + if (isOpen && formData.date) { + fetchProducts(); + } +}, [formData.date, isOpen]); +``` + +## Deletion Process Flow + +### 1. User Initiates Delete +- User clicks "Delete" button on a product +- Confirmation modal appears + +### 2. Backend Processing +```python +# Simple application code - trigger handles the complexity +product.deleted = True +product.valid_from = date.today() # Manual versioning date +product.updated_at = func.now() + +# Trigger automatically: +# 1. Detects the change (deleted field + valid_from change) +# 2. Creates history record with old data (deleted=False, valid_to=today) +# 3. Ensures new record has valid_to='9999-12-31' +``` + +**Trigger Logic (Automatic)**: +- Detects manual versioning because `valid_from` changed +- Uses the new `valid_from` as the cutoff date for history +- Creates history record: `{...old_data, valid_to: new_valid_from, operation: 'U'}` +- No additional application logic needed + +### 3. Frontend Updates +- Product list refreshes +- Deleted product appears with visual indicators (if "Show deleted" is enabled) +- Product becomes unavailable for new shopping events + +## Historical Data Integrity + +### Shopping Events +- **Guarantee**: Shopping events always show products exactly as they existed when purchased +- **Implementation**: Uses `/products/{id}/at/{date}` endpoint to fetch historical product state +- **Benefit**: Even if a product is deleted later, historical shopping events remain accurate + +### Audit Trail +- **Complete History**: All product versions are preserved in `products_history` +- **Deletion Tracking**: History records show when and why products were deleted +- **Temporal Queries**: Can reconstruct product state at any point in time + +## Usage Examples + +### 1. View All Products (Default) +```bash +GET /products/ +# Returns only non-deleted products +``` + +### 2. View All Products Including Deleted +```bash +GET /products/?show_deleted=true +# Returns all products with deleted status +``` + +### 3. Get Products Available for Shopping on Specific Date +```bash +GET /products/available-for-shopping/2024-01-15 +# Returns products that were not deleted on 2024-01-15 +``` + +### 4. View Historical Shopping Event +```bash +GET /shopping-events/123/products-as-purchased +# Returns products exactly as they were when purchased, regardless of current deletion status +``` + +## Benefits + +1. **Data Preservation**: No data is ever lost +2. **Audit Compliance**: Complete audit trail of all changes +3. **Historical Accuracy**: Shopping events remain accurate over time +4. **User Experience**: Clean interface with optional deleted product visibility +5. **Flexibility**: Easy to "undelete" products if needed (future enhancement) + +## Future Enhancements + +1. **Undelete Functionality**: Add ability to restore deleted products +2. **Bulk Operations**: Delete/restore multiple products at once +3. **Deletion Reasons**: Add optional reason field for deletions +4. **Advanced Filtering**: Filter by deletion date, reason, etc. +5. **Reporting**: Generate reports on deleted products and their impact + +## Migration Instructions + +1. **Run Migration**: Execute `temporal_migration.sql` to add `deleted` column +2. **Deploy Backend**: Update backend with new API endpoints and logic +3. **Deploy Frontend**: Update frontend with new UI components and API calls +4. **Test**: Verify soft delete functionality and historical data integrity + +## Testing Scenarios + +1. **Basic Deletion**: Delete a product and verify it's hidden from default view +2. **Show Deleted Toggle**: Enable "Show deleted" and verify deleted products appear with proper styling +3. **Shopping Event Filtering**: Create shopping event and verify deleted products don't appear in product list +4. **Historical Accuracy**: Delete a product that was in a past shopping event, verify the shopping event still shows correct historical data +5. **Date-based Filtering**: Test `/products/available-for-shopping/{date}` with various dates before/after product deletions + +## Database Initialization + +### ⚠️ Important: Trigger Creation + +The temporal triggers are essential for the soft delete functionality. They must be created in **all environments**: + +### **Method 1: Automatic (Recommended)** +The triggers are now automatically created when using SQLAlchemy's `create_all()`: + +```python +# This now creates both tables AND triggers +models.Base.metadata.create_all(bind=engine) +``` + +**How it works**: +- SQLAlchemy event listener detects when `ProductHistory` table is created +- Automatically executes trigger creation SQL +- Works for fresh dev, test, and production databases + +### **Method 2: Manual Database Script** +For explicit control, use the initialization script: + +```bash +# Run this for fresh database setup +python backend/database_init.py +``` + +**Features**: +- Creates all tables +- Creates all triggers +- Checks for existing triggers (safe to run multiple times) +- Provides detailed feedback + +### **Method 3: Migration File** +For existing databases, run the migration: + +```sql +-- Execute temporal_migration.sql +\i temporal_migration.sql +``` + +## Environment Setup Guide + +### **Development (Fresh DB)** +```bash +# Option A: Automatic (when starting app) +python backend/main.py +# ✅ Tables + triggers created automatically + +# Option B: Explicit setup +python backend/database_init.py +python backend/main.py +``` + +### **Production (Fresh DB)** +```bash +# Recommended: Explicit initialization +python backend/database_init.py +# Then start the application +``` + +### **Existing Database (Migration)** +```bash +# Apply migration to add soft delete functionality +docker-compose exec db psql -U postgres -d groceries -f /tmp/temporal_migration.sql +``` \ No newline at end of file diff --git a/TEMPORAL_FEATURES.md b/TEMPORAL_FEATURES.md new file mode 100644 index 0000000..146080e --- /dev/null +++ b/TEMPORAL_FEATURES.md @@ -0,0 +1,111 @@ +# Temporal Product Tracking Features + +This document describes the new historical product tracking functionality that allows you to track product changes over time. + +## Features + +### 1. Historical Product Versioning +- Products now maintain a complete history of changes +- When product attributes (name, weight, category, etc.) are updated, the old version is automatically saved +- Each version has `valid_from` and `valid_to` dates indicating when it was active + +### 2. Manual Effective Dates +- When creating or editing products, you can specify a custom "Effective From" date +- If not specified, the current date is used +- This allows you to retroactively record product changes or schedule future changes + +### 3. Shopping Event Historical Accuracy +- Shopping events now show products exactly as they were when purchased +- Even if a product's weight or name has changed since purchase, the historical data is preserved + +## Database Changes + +### New Tables +- `products_history` - Stores old versions of products when they're updated + +### New Columns +- `products.valid_from` (DATE) - When this product version became effective +- `products.valid_to` (DATE) - When this product version was superseded (9999-12-31 for current versions) + +## API Endpoints + +### New Endpoints +- `GET /current-date` - Get current date for form prefilling +- `GET /products/{id}/history` - Get all historical versions of a product +- `GET /products/{id}/at/{date}` - Get product as it existed on a specific date (YYYY-MM-DD) +- `GET /shopping-events/{id}/products-as-purchased` - Get products as they were when purchased + +### Updated Endpoints +- `POST /products/` - Now accepts optional `valid_from` field +- `PUT /products/{id}` - Now accepts optional `valid_from` field for manual versioning + +## Frontend Changes + +### Product Forms +- Added "Effective From" date field to product create/edit forms +- Date field is pre-filled with current date +- Required field with helpful description + +### API Integration +- ProductCreate interface now includes optional `valid_from` field +- New utilityApi for fetching current date +- Proper form validation and error handling + +## Migration + +Run `temporal_migration.sql` to: +1. Add temporal columns to existing products table +2. Create products_history table +3. Set up automatic versioning trigger +4. Initialize existing products with baseline date (2025-05-01) + +## Usage Examples + +### Creating a Product with Custom Date +```json +POST /products/ +{ + "name": "Organic Milk", + "category_id": 1, + "weight": 1000, + "weight_unit": "ml", + "valid_from": "2025-03-15" +} +``` + +### Updating a Product with Future Effective Date +```json +PUT /products/123 +{ + "weight": 1200, + "valid_from": "2025-04-01" +} +``` + +### Getting Historical Product Data +```bash +# Get product as it was on January 15, 2025 +GET /products/123/at/2025-01-15 + +# Get all versions of a product +GET /products/123/history + +# Get shopping event with historical product data +GET /shopping-events/456/products-as-purchased +``` + +## Benefits + +1. **Complete Audit Trail** - Never lose track of how products have changed over time +2. **Accurate Historical Data** - Shopping events always show correct product information +3. **Flexible Dating** - Record changes retroactively or schedule future changes +4. **Automatic Versioning** - No manual effort required for basic updates +5. **Cross-Database Compatibility** - Uses standard DATE fields that work with PostgreSQL, SQLite, MySQL, etc. + +## Technical Notes + +- Versioning is handled automatically by database triggers +- Manual versioning is used when custom `valid_from` dates are specified +- Date format: YYYY-MM-DD (ISO 8601) +- Far future date (9999-12-31) represents current/active versions +- Temporal fields are not displayed in regular product lists (by design) \ No newline at end of file diff --git a/backend/database_init.py b/backend/database_init.py new file mode 100644 index 0000000..b00d202 --- /dev/null +++ b/backend/database_init.py @@ -0,0 +1,63 @@ +#!/usr/bin/env python3 +""" +Database initialization script that creates all tables and triggers. +Use this for setting up fresh development or production databases. + +Usage: + python database_init.py +""" + +import sys +import os +from sqlalchemy import create_engine, text +from sqlalchemy.orm import sessionmaker + +# Add parent directory to path to import models +sys.path.append(os.path.dirname(os.path.dirname(os.path.abspath(__file__)))) + +from models import Base +from database import get_database_url + +def init_database(): + """Initialize database with all tables and triggers""" + + database_url = get_database_url() + engine = create_engine(database_url) + + print("🚀 Initializing database...") + print(f"📍 Database URL: {database_url}") + + try: + # Create all tables + print("📊 Creating tables...") + Base.metadata.create_all(bind=engine) + print("✅ Tables created successfully") + + # Create triggers (if not already created by event listener) + print("⚙️ Ensuring triggers are created...") + with engine.connect() as connection: + # Check if trigger exists + result = connection.execute(text(""" + SELECT EXISTS ( + SELECT 1 FROM information_schema.triggers + WHERE trigger_name = 'products_versioning_trigger' + ); + """)).scalar() + + if not result: + print("📝 Creating products versioning trigger...") + from models import PRODUCTS_VERSIONING_TRIGGER_SQL + connection.execute(text(PRODUCTS_VERSIONING_TRIGGER_SQL)) + connection.commit() + print("✅ Trigger created successfully") + else: + print("✅ Trigger already exists") + + print("🎉 Database initialization completed successfully!") + + except Exception as e: + print(f"❌ Error initializing database: {e}") + sys.exit(1) + +if __name__ == "__main__": + init_database() \ No newline at end of file diff --git a/backend/main.py b/backend/main.py index 5eae58b..13e5302 100644 --- a/backend/main.py +++ b/backend/main.py @@ -1,7 +1,7 @@ from fastapi import FastAPI, Depends, HTTPException, status from fastapi.middleware.cors import CORSMiddleware from sqlalchemy.orm import Session -from sqlalchemy import text +from sqlalchemy import text, func from typing import List import models, schemas from database import engine, get_db @@ -95,6 +95,34 @@ def build_shopping_event_response(event: models.ShoppingEvent, db: Session) -> s def read_root(): return {"message": __app_name__, "version": __version__, "name": "Groceries Tracker Backend"} +# Utility endpoints +@app.get("/current-date") +def get_current_date(): + """Get current date for use as default in valid_from fields""" + from datetime import date + return {"current_date": date.today().isoformat()} + +@app.get("/products/available-for-shopping/{shopping_date}", response_model=List[schemas.Product]) +def get_products_available_for_shopping(shopping_date: str, db: Session = Depends(get_db)): + """Get products that were available (not deleted) on a specific shopping date""" + from datetime import datetime + + try: + # Parse the shopping date + target_date = datetime.strptime(shopping_date, '%Y-%m-%d').date() + except ValueError: + raise HTTPException(status_code=400, detail="Invalid date format. Use YYYY-MM-DD format") + + # Get products that were either: + # 1. Never deleted (deleted=False) + # 2. Deleted after the shopping date (valid_from > shopping_date for deleted=True products) + products = db.query(models.Product).filter( + (models.Product.deleted == False) | + ((models.Product.deleted == True) & (models.Product.valid_from > target_date)) + ).all() + + return products + # Product endpoints @app.post("/products/", response_model=schemas.Product) def create_product(product: schemas.ProductCreate, db: Session = Depends(get_db)): @@ -109,15 +137,31 @@ def create_product(product: schemas.ProductCreate, db: Session = Depends(get_db) if brand is None: raise HTTPException(status_code=404, detail="Brand not found") - db_product = models.Product(**product.dict()) + # Validate valid_from date if provided + if product.valid_from is not None: + from datetime import date + if product.valid_from > date.today(): + raise HTTPException(status_code=400, detail="Valid from date cannot be in the future") + + # Create product data + product_data = product.dict(exclude={'valid_from'}) + db_product = models.Product(**product_data) + + # Set valid_from if provided, otherwise let database default handle it + if product.valid_from is not None: + db_product.valid_from = product.valid_from + db.add(db_product) db.commit() db.refresh(db_product) return db_product @app.get("/products/", response_model=List[schemas.Product]) -def read_products(skip: int = 0, limit: int = 100, db: Session = Depends(get_db)): - products = db.query(models.Product).offset(skip).limit(limit).all() +def read_products(skip: int = 0, limit: int = 100, show_deleted: bool = False, db: Session = Depends(get_db)): + query = db.query(models.Product) + if not show_deleted: + query = query.filter(models.Product.deleted == False) + products = query.offset(skip).limit(limit).all() return products @app.get("/products/{product_id}", response_model=schemas.Product) @@ -127,13 +171,21 @@ def read_product(product_id: int, db: Session = Depends(get_db)): raise HTTPException(status_code=404, detail="Product not found") return product +@app.get("/products/{product_id}/valid-from") +def get_product_valid_from(product_id: int, db: Session = Depends(get_db)): + """Get the current valid_from date for a product (used for validation when editing)""" + product = db.query(models.Product).filter(models.Product.id == product_id).first() + if product is None: + raise HTTPException(status_code=404, detail="Product not found") + return {"valid_from": product.valid_from.isoformat()} + @app.put("/products/{product_id}", response_model=schemas.Product) def update_product(product_id: int, product_update: schemas.ProductUpdate, db: Session = Depends(get_db)): product = db.query(models.Product).filter(models.Product.id == product_id).first() if product is None: raise HTTPException(status_code=404, detail="Product not found") - update_data = product_update.dict(exclude_unset=True) + update_data = product_update.dict(exclude_unset=True, exclude={'valid_from'}) # Validate category exists if category_id is being updated if 'category_id' in update_data: @@ -147,9 +199,32 @@ def update_product(product_id: int, product_update: schemas.ProductUpdate, db: S if brand is None: raise HTTPException(status_code=404, detail="Brand not found") + # Validate valid_from date if provided + if product_update.valid_from is not None: + from datetime import date + if product_update.valid_from > date.today(): + raise HTTPException(status_code=400, detail="Valid from date cannot be in the future") + if product_update.valid_from <= product.valid_from: + raise HTTPException( + status_code=400, + detail=f"Valid from date must be after the current product's valid from date ({product.valid_from})" + ) + + # Check if any versioned fields are actually changing + versioned_fields = ['name', 'category_id', 'brand_id', 'organic', 'weight', 'weight_unit'] + has_changes = any( + field in update_data and getattr(product, field) != update_data[field] + for field in versioned_fields + ) + + # Apply the updates - trigger will handle history creation automatically for field, value in update_data.items(): setattr(product, field, value) + # Set valid_from if provided for manual versioning + if product_update.valid_from is not None: + product.valid_from = product_update.valid_from + db.commit() db.refresh(product) return product @@ -160,10 +235,163 @@ def delete_product(product_id: int, db: Session = Depends(get_db)): if product is None: raise HTTPException(status_code=404, detail="Product not found") - db.delete(product) + if product.deleted: + raise HTTPException(status_code=400, detail="Product is already deleted") + + from datetime import date + + # Simply mark as deleted and set valid_from to today + # The trigger will automatically create the history record + product.deleted = True + product.valid_from = date.today() + product.updated_at = func.now() + db.commit() return {"message": "Product deleted successfully"} +# Historical Product endpoints +@app.get("/products/{product_id}/history", response_model=List[schemas.ProductHistory]) +def get_product_history(product_id: int, db: Session = Depends(get_db)): + """Get all historical versions of a product""" + # Check if product exists + product = db.query(models.Product).filter(models.Product.id == product_id).first() + if product is None: + raise HTTPException(status_code=404, detail="Product not found") + + # Get history from history table + history = db.query(models.ProductHistory).filter( + models.ProductHistory.id == product_id + ).order_by(models.ProductHistory.valid_from.desc()).all() + + return history + +@app.get("/products/{product_id}/at/{date}", response_model=schemas.ProductAtDate) +def get_product_at_date(product_id: int, date: str, db: Session = Depends(get_db)): + """Get product as it existed at a specific date - CRUCIAL for shopping events""" + from datetime import datetime, date as date_type + + try: + # Parse the date string (accept YYYY-MM-DD format) + target_date = datetime.strptime(date, '%Y-%m-%d').date() + except ValueError: + raise HTTPException(status_code=400, detail="Invalid date format. Use YYYY-MM-DD format") + + # First try current products table + current_product = db.query(models.Product).filter( + models.Product.id == product_id, + models.Product.valid_from <= target_date, + models.Product.valid_to >= target_date + ).first() + + if current_product: + # Get related data + category = db.query(models.GroceryCategory).filter( + models.GroceryCategory.id == current_product.category_id + ).first() + brand = None + if current_product.brand_id: + brand = db.query(models.Brand).filter( + models.Brand.id == current_product.brand_id + ).first() + + return schemas.ProductAtDate( + id=current_product.id, + name=current_product.name, + category_id=current_product.category_id, + category=category, + brand_id=current_product.brand_id, + brand=brand, + organic=current_product.organic, + weight=current_product.weight, + weight_unit=current_product.weight_unit, + valid_from=current_product.valid_from, + valid_to=current_product.valid_to, + deleted=current_product.deleted, + was_current=True + ) + + # Try history table + historical_product = db.query(models.ProductHistory).filter( + models.ProductHistory.id == product_id, + models.ProductHistory.valid_from <= target_date, + models.ProductHistory.valid_to >= target_date + ).first() + + if historical_product: + # Get related data (note: these might have changed too, but we'll use current versions) + category = db.query(models.GroceryCategory).filter( + models.GroceryCategory.id == historical_product.category_id + ).first() + brand = None + if historical_product.brand_id: + brand = db.query(models.Brand).filter( + models.Brand.id == historical_product.brand_id + ).first() + + return schemas.ProductAtDate( + id=historical_product.id, + name=historical_product.name, + category_id=historical_product.category_id, + category=category, + brand_id=historical_product.brand_id, + brand=brand, + organic=historical_product.organic, + weight=historical_product.weight, + weight_unit=historical_product.weight_unit, + valid_from=historical_product.valid_from, + valid_to=historical_product.valid_to, + deleted=historical_product.deleted, + was_current=False + ) + + # Product didn't exist at that date + raise HTTPException( + status_code=404, + detail=f"Product {product_id} did not exist on {date}" + ) + +@app.get("/shopping-events/{event_id}/products-as-purchased", response_model=List[schemas.ProductAtPurchase]) +def get_shopping_event_products_as_purchased(event_id: int, db: Session = Depends(get_db)): + """Get products as they were when purchased - shows historical product data""" + # Get the shopping event + event = db.query(models.ShoppingEvent).filter(models.ShoppingEvent.id == event_id).first() + if event is None: + raise HTTPException(status_code=404, detail="Shopping event not found") + + # Get products from association table + products_data = db.execute( + text(""" + SELECT sep.product_id, sep.amount, sep.price, sep.discount + FROM shopping_event_products sep + WHERE sep.shopping_event_id = :event_id + """), + {"event_id": event_id} + ).fetchall() + + result = [] + for product_data in products_data: + # Get product as it was at the time of purchase + try: + # Extract just the date from the shopping event datetime + purchase_date = event.date.date().strftime('%Y-%m-%d') + product_at_purchase = get_product_at_date( + product_data.product_id, + purchase_date, + db + ) + + result.append(schemas.ProductAtPurchase( + product=product_at_purchase, + amount=product_data.amount, + price=product_data.price, + discount=product_data.discount + )) + except HTTPException: + # Product didn't exist at purchase time (shouldn't happen, but handle gracefully) + continue + + return result + # Shop endpoints @app.post("/shops/", response_model=schemas.Shop) def create_shop(shop: schemas.ShopCreate, db: Session = Depends(get_db)): diff --git a/backend/models.py b/backend/models.py index eedd87f..2f9b88d 100644 --- a/backend/models.py +++ b/backend/models.py @@ -1,11 +1,89 @@ -from sqlalchemy import Column, Integer, String, Float, Boolean, DateTime, ForeignKey, Table +from sqlalchemy import Column, Integer, String, Float, Boolean, DateTime, Date, ForeignKey, Table, event, DDL from sqlalchemy.ext.declarative import declarative_base from sqlalchemy.orm import relationship -from sqlalchemy.sql import func +from sqlalchemy.sql import func, text from datetime import datetime +# Constants for temporal tables +FAR_FUTURE_DATE = "'9999-12-31'" + Base = declarative_base() +# Trigger creation SQL +PRODUCTS_VERSIONING_TRIGGER_SQL = """ +CREATE OR REPLACE FUNCTION products_versioning_trigger() +RETURNS TRIGGER AS $$ +BEGIN + -- Handle DELETE operations + IF TG_OP = 'DELETE' THEN + -- Create history record for the deleted product + INSERT INTO products_history ( + id, name, category_id, brand_id, organic, weight, weight_unit, + created_at, updated_at, valid_from, valid_to, deleted, operation + ) VALUES ( + OLD.id, OLD.name, OLD.category_id, OLD.brand_id, OLD.organic, + OLD.weight, OLD.weight_unit, OLD.created_at, OLD.updated_at, + OLD.valid_from, CURRENT_DATE, OLD.deleted, 'D' + ); + + RETURN OLD; + END IF; + + -- Handle UPDATE operations + IF TG_OP = 'UPDATE' THEN + -- Check if any versioned fields have changed + IF (OLD.name IS DISTINCT FROM NEW.name OR + OLD.category_id IS DISTINCT FROM NEW.category_id OR + OLD.brand_id IS DISTINCT FROM NEW.brand_id OR + OLD.organic IS DISTINCT FROM NEW.organic OR + OLD.weight IS DISTINCT FROM NEW.weight OR + OLD.weight_unit IS DISTINCT FROM NEW.weight_unit OR + OLD.deleted IS DISTINCT FROM NEW.deleted) THEN + + -- Determine the valid_to date for the history record + DECLARE + history_valid_to DATE; + BEGIN + -- If valid_from was manually changed, use that as the cutoff + -- Otherwise, use current date for automatic versioning + IF OLD.valid_from IS DISTINCT FROM NEW.valid_from THEN + history_valid_to = NEW.valid_from; + ELSE + history_valid_to = CURRENT_DATE; + -- For automatic versioning, update the valid_from to today + NEW.valid_from = CURRENT_DATE; + END IF; + + -- Create history record with the old data + INSERT INTO products_history ( + id, name, category_id, brand_id, organic, weight, weight_unit, + created_at, updated_at, valid_from, valid_to, deleted, operation + ) VALUES ( + OLD.id, OLD.name, OLD.category_id, OLD.brand_id, OLD.organic, + OLD.weight, OLD.weight_unit, OLD.created_at, OLD.updated_at, + OLD.valid_from, history_valid_to, OLD.deleted, 'U' + ); + END; + + -- Always ensure valid_to is set to far future for current version + NEW.valid_to = '9999-12-31'; + NEW.updated_at = NOW(); + END IF; + + RETURN NEW; + END IF; + + RETURN NULL; +END; +$$ LANGUAGE plpgsql; + +DROP TRIGGER IF EXISTS products_versioning_trigger ON products; +CREATE TRIGGER products_versioning_trigger + BEFORE UPDATE OR DELETE ON products + FOR EACH ROW + EXECUTE FUNCTION products_versioning_trigger(); +""" + # Association table for many-to-many relationship between shopping events and products shopping_event_products = Table( 'shopping_event_products', @@ -78,6 +156,11 @@ class Product(Base): created_at = Column(DateTime(timezone=True), server_default=func.now()) updated_at = Column(DateTime(timezone=True), onupdate=func.now()) + # Temporal columns for versioning + valid_from = Column(Date, server_default=func.current_date(), nullable=False) + valid_to = Column(Date, server_default=text(FAR_FUTURE_DATE), nullable=False) + deleted = Column(Boolean, default=False, nullable=False) + # Relationships category = relationship("GroceryCategory", back_populates="products") brand = relationship("Brand", back_populates="products") @@ -93,6 +176,41 @@ class Product(Base): viewonly=True ) +class ProductHistory(Base): + __tablename__ = "products_history" + + history_id = Column(Integer, primary_key=True, index=True) + id = Column(Integer, nullable=False, index=True) # Original product ID + name = Column(String, nullable=False) + category_id = Column(Integer, nullable=False) + brand_id = Column(Integer, nullable=True) + organic = Column(Boolean, default=False) + weight = Column(Float, nullable=True) + weight_unit = Column(String, default="piece") + created_at = Column(DateTime(timezone=True)) + updated_at = Column(DateTime(timezone=True)) + + # Temporal columns + valid_from = Column(Date, nullable=False) + valid_to = Column(Date, nullable=False) + deleted = Column(Boolean, default=False, nullable=False) + + # Audit columns + operation = Column(String(1), nullable=False) # 'U' for Update, 'D' for Delete + archived_at = Column(DateTime(timezone=True), server_default=func.now(), nullable=False) + +# Create trigger after ProductHistory table is created +@event.listens_for(ProductHistory.__table__, 'after_create') +def create_products_versioning_trigger(target, connection, **kw): + """Create the products versioning trigger after the history table is created""" + try: + connection.execute(text(PRODUCTS_VERSIONING_TRIGGER_SQL)) + print("✅ Products versioning trigger created successfully") + except Exception as e: + print(f"⚠️ Warning: Could not create products versioning trigger: {e}") + # Don't fail the entire application startup if trigger creation fails + pass + class Shop(Base): __tablename__ = "shops" diff --git a/backend/schemas.py b/backend/schemas.py index 6f3ba4f..8be672d 100644 --- a/backend/schemas.py +++ b/backend/schemas.py @@ -1,6 +1,6 @@ from pydantic import BaseModel, Field from typing import Optional, List -from datetime import datetime +from datetime import datetime, date # Brand schemas class BrandBase(BaseModel): @@ -70,7 +70,7 @@ class ProductBase(BaseModel): weight_unit: str = "g" class ProductCreate(ProductBase): - pass + valid_from: Optional[date] = None # If not provided, will use current date class ProductUpdate(BaseModel): name: Optional[str] = None @@ -79,6 +79,7 @@ class ProductUpdate(BaseModel): organic: Optional[bool] = None weight: Optional[float] = None weight_unit: Optional[str] = None + valid_from: Optional[date] = None # If not provided, will use current date class Product(ProductBase): id: int @@ -90,6 +91,54 @@ class Product(ProductBase): class Config: from_attributes = True +# Historical Product schemas +class ProductHistory(BaseModel): + history_id: int + id: int # Original product ID + name: str + category_id: int + brand_id: Optional[int] = None + organic: bool = False + weight: Optional[float] = None + weight_unit: str = "g" + created_at: Optional[datetime] = None + updated_at: Optional[datetime] = None + valid_from: date + valid_to: date + deleted: bool + operation: str # 'U' for Update, 'D' for Delete + archived_at: datetime + + class Config: + from_attributes = True + +class ProductAtDate(BaseModel): + id: int + name: str + category_id: int + category: GroceryCategory + brand_id: Optional[int] = None + brand: Optional[Brand] = None + organic: bool = False + weight: Optional[float] = None + weight_unit: str = "g" + valid_from: date + valid_to: date + deleted: bool + was_current: bool # True if from current table, False if from history + + class Config: + from_attributes = True + +class ProductAtPurchase(BaseModel): + product: ProductAtDate + amount: float + price: float + discount: bool + + class Config: + from_attributes = True + # Shop schemas class ShopBase(BaseModel): name: str diff --git a/backend/version.py b/backend/version.py index 7420c90..01c3c7e 100644 --- a/backend/version.py +++ b/backend/version.py @@ -3,6 +3,6 @@ Version configuration for Groceries Tracker Backend Single source of truth for version information """ -__version__ = "1.0.0" +__version__ = "1.1.0" __app_name__ = "Groceries Tracker API" -__description__ = "API for tracking grocery shopping events, products, and expenses" \ No newline at end of file +__description__ = "API for tracking grocery shopping events, products, and expenses with historical data support" \ No newline at end of file diff --git a/frontend/package.json b/frontend/package.json index b2b704f..d640248 100644 --- a/frontend/package.json +++ b/frontend/package.json @@ -1,6 +1,6 @@ { "name": "groceries-tracker-frontend", - "version": "1.0.1", + "version": "1.1.0", "private": true, "dependencies": { "@types/node": "^20.10.5", diff --git a/frontend/src/components/AddProductModal.tsx b/frontend/src/components/AddProductModal.tsx index 27eaab7..927e030 100644 --- a/frontend/src/components/AddProductModal.tsx +++ b/frontend/src/components/AddProductModal.tsx @@ -1,5 +1,5 @@ import React, { useState, useEffect, useCallback } from 'react'; -import { productApi, brandApi, groceryCategoryApi } from '../services/api'; +import { productApi, brandApi, groceryCategoryApi, utilityApi } from '../services/api'; import { Product, Brand, GroceryCategory } from '../types'; import { useBodyScrollLock } from '../hooks/useBodyScrollLock'; @@ -18,6 +18,7 @@ interface ProductFormData { organic: boolean; weight?: number; weight_unit: string; + valid_from: string; // ISO date string (YYYY-MM-DD) } const AddProductModal: React.FC = ({ isOpen, onClose, onProductAdded, editProduct, duplicateProduct }) => { @@ -27,12 +28,15 @@ const AddProductModal: React.FC = ({ isOpen, onClose, onPr brand_id: undefined, organic: false, weight: undefined, - weight_unit: 'piece' + weight_unit: 'piece', + valid_from: '' }); const [brands, setBrands] = useState([]); const [categories, setCategories] = useState([]); const [loading, setLoading] = useState(false); const [error, setError] = useState(''); + const [currentDate, setCurrentDate] = useState(''); + const [minValidFromDate, setMinValidFromDate] = useState(''); const weightUnits = ['piece', 'g', 'kg', 'lb', 'oz', 'ml', 'l']; @@ -44,6 +48,7 @@ const AddProductModal: React.FC = ({ isOpen, onClose, onPr if (isOpen) { fetchBrands(); fetchCategories(); + fetchCurrentDate(); } }, [isOpen]); @@ -65,52 +70,113 @@ const AddProductModal: React.FC = ({ isOpen, onClose, onPr } }; + const fetchCurrentDate = async () => { + try { + const response = await utilityApi.getCurrentDate(); + // Only update if valid_from is not already set + setFormData(prev => ({ + ...prev, + valid_from: prev.valid_from || response.data.current_date + })); + setCurrentDate(response.data.current_date); + setMinValidFromDate(response.data.current_date); + } catch (err) { + console.error('Failed to fetch current date:', err); + // Fallback to current date if API fails + const today = new Date().toISOString().split('T')[0]; + setFormData(prev => ({ + ...prev, + valid_from: prev.valid_from || today + })); + setCurrentDate(today); + setMinValidFromDate(today); + } + }; + // Populate form when editing or duplicating useEffect(() => { - if (editProduct) { + if (editProduct && isOpen) { + // For editing, fetch the current valid_from to set proper constraints + const fetchProductValidFrom = async () => { + try { + const response = await productApi.getValidFromDate(editProduct.id); + const currentValidFrom = response.data.valid_from; + setMinValidFromDate(currentValidFrom); + + setFormData({ + name: editProduct.name, + category_id: editProduct.category_id, + brand_id: editProduct.brand_id, + organic: editProduct.organic, + weight: editProduct.weight, + weight_unit: editProduct.weight_unit, + valid_from: currentDate // Default to today for edits + }); + } catch (err) { + console.error('Failed to fetch product valid_from:', err); + setError('Failed to load product data for editing'); + } + }; + + if (currentDate) { + fetchProductValidFrom(); + } + } else if (duplicateProduct && isOpen) { + // For duplicating, use today as default and allow any date <= today + setMinValidFromDate('1900-01-01'); // No restriction for new products setFormData({ - name: editProduct.name, - category_id: editProduct.category_id, - brand_id: editProduct.brand_id, - organic: editProduct.organic, - weight: editProduct.weight, - weight_unit: editProduct.weight_unit - }); - } else if (duplicateProduct) { - setFormData({ - name: duplicateProduct.name, + name: `${duplicateProduct.name} (Copy)`, category_id: duplicateProduct.category_id, brand_id: duplicateProduct.brand_id, organic: duplicateProduct.organic, weight: duplicateProduct.weight, - weight_unit: duplicateProduct.weight_unit + weight_unit: duplicateProduct.weight_unit, + valid_from: currentDate }); - } else { - // Reset form for adding new product + } else if (isOpen && currentDate) { + // For new products, allow any date <= today + setMinValidFromDate('1900-01-01'); // No restriction for new products setFormData({ name: '', category_id: undefined, brand_id: undefined, organic: false, weight: undefined, - weight_unit: 'piece' + weight_unit: 'piece', + valid_from: currentDate }); } - setError(''); - }, [editProduct, duplicateProduct, isOpen]); + }, [editProduct, duplicateProduct, isOpen, currentDate]); const handleSubmit = useCallback(async (e: React.FormEvent) => { e.preventDefault(); - if (!formData.name.trim() || !formData.category_id) { + if (!formData.name.trim() || !formData.category_id || !formData.valid_from) { setError('Please fill in all required fields with valid values'); return; } + // Validate date constraints + const validFromDate = new Date(formData.valid_from); + const today = new Date(currentDate); + + if (validFromDate > today) { + setError('Valid from date cannot be in the future'); + return; + } + + if (editProduct) { + const minDate = new Date(minValidFromDate); + if (validFromDate <= minDate) { + setError(`Valid from date must be after the current product's valid from date (${minValidFromDate})`); + return; + } + } + try { setLoading(true); setError(''); - const productData = { + const productData: any = { name: formData.name.trim(), category_id: formData.category_id!, brand_id: formData.brand_id || undefined, @@ -118,6 +184,11 @@ const AddProductModal: React.FC = ({ isOpen, onClose, onPr weight: formData.weight || undefined, weight_unit: formData.weight_unit }; + + // Only include valid_from if it's provided + if (formData.valid_from) { + productData.valid_from = formData.valid_from; + } if (editProduct) { // Update existing product @@ -134,7 +205,8 @@ const AddProductModal: React.FC = ({ isOpen, onClose, onPr brand_id: undefined, organic: false, weight: undefined, - weight_unit: 'piece' + weight_unit: 'piece', + valid_from: '' }); onProductAdded(); @@ -145,7 +217,7 @@ const AddProductModal: React.FC = ({ isOpen, onClose, onPr } finally { setLoading(false); } - }, [formData, editProduct, onProductAdded, onClose]); + }, [formData, editProduct, onProductAdded, onClose, currentDate, minValidFromDate]); useEffect(() => { if (!isOpen) return; @@ -228,10 +300,37 @@ const AddProductModal: React.FC = ({ isOpen, onClose, onPr onChange={handleChange} required className="mt-1 block w-full px-3 py-2 border border-gray-300 rounded-md shadow-sm focus:outline-none focus:ring-blue-500 focus:border-blue-500" - placeholder="e.g., Whole Foods Organic Milk" + placeholder="Product name" /> +
+ + { + const nextDay = new Date(minValidFromDate); + nextDay.setDate(nextDay.getDate() + 1); + return nextDay.toISOString().split('T')[0]; + })() : undefined} + max={currentDate} + className="mt-1 block w-full px-3 py-2 border border-gray-300 rounded-md shadow-sm focus:outline-none focus:ring-blue-500 focus:border-blue-500" + /> +

+ {editProduct + ? `Must be after ${minValidFromDate} and not in the future` + : 'The date when this product information becomes effective (cannot be in the future)' + } +

+
+
-
+
@@ -494,10 +505,10 @@ const AddShoppingEventModal: React.FC = ({ placeholder="1" value={newProductItem.amount} onChange={(e) => setNewProductItem({...newProductItem, amount: parseFloat(e.target.value)})} - className="w-full h-10 border border-gray-300 rounded-md px-3 py-2 focus:outline-none focus:ring-2 focus:ring-blue-500" + className="w-24 h-10 border border-gray-300 rounded-md px-3 py-2 focus:outline-none focus:ring-2 focus:ring-blue-500" />
-
+
@@ -508,165 +519,133 @@ const AddShoppingEventModal: React.FC = ({ placeholder="0.00" value={newProductItem.price} onChange={(e) => setNewProductItem({...newProductItem, price: parseFloat(e.target.value)})} - className="w-full h-10 border border-gray-300 rounded-md px-3 py-2 focus:outline-none focus:ring-2 focus:ring-blue-500" + className="w-24 h-10 border border-gray-300 rounded-md px-3 py-2 focus:outline-none focus:ring-2 focus:ring-blue-500" />
-
- -
+
+
-
-
- +
+
- {formData.shop_id > 0 && ( -

- {shopBrands.length === 0 - ? `Showing all ${products.length} products (no brand restrictions for this shop)` - : `Showing ${getFilteredProducts().length} of ${products.length} products (filtered by shop's available brands)` - } -

- )} - {/* Selected Products List */} - {selectedProducts.length > 0 && ( -
-

Selected Items:

- {Object.entries( - selectedProducts.reduce((groups, item, index) => { - const product = products.find(p => p.id === item.product_id); - const category = product?.category.name || 'Unknown'; - if (!groups[category]) { - groups[category] = []; - } - groups[category].push({ ...item, index }); - return groups; - }, {} as Record) - ) - .sort(([a], [b]) => a.localeCompare(b)) - .map(([category, categoryItems]) => ( -
-
- {category} -
- {categoryItems.map((item) => ( -
-
-
- {getProductName(item.product_id)} -
-
- {item.amount} × ${item.price.toFixed(2)} = ${(item.amount * item.price).toFixed(2)} - {item.discount && 🏷️} -
-
-
- - -
-
- ))} -
- ))} -
- )} +
+ + + + + + + + + + + + + {selectedProducts.map((product, index) => ( + + + + + + + + + ))} + +
+ Product + + Amount + + Price ($) + + Discount + + Total ($) + + Edit +
+ {getProductName(product.product_id)} + + {product.amount} + + {product.price.toFixed(2)} + + {product.discount ? 'Yes' : 'No'} + + {(product.amount * product.price).toFixed(2)} + + + +
+
- {/* Total Amount */} -
-
-