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:
@@ -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"
|
||||
|
||||
|
||||
Reference in New Issue
Block a user