Minor version bump (1.x.0) is appropriate because:
✅ New functionality added (soft delete system) ✅ Backward compatible (existing features unchanged) ✅ Significant enhancement (complete temporal tracking system) ✅ API additions (new endpoints, parameters) ✅ UI enhancements (new components, visual indicators)
This commit is contained in:
63
backend/database_init.py
Normal file
63
backend/database_init.py
Normal file
@@ -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()
|
||||
240
backend/main.py
240
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)):
|
||||
|
||||
@@ -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"
|
||||
|
||||
|
||||
@@ -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
|
||||
|
||||
@@ -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"
|
||||
__description__ = "API for tracking grocery shopping events, products, and expenses with historical data support"
|
||||
Reference in New Issue
Block a user