-- Inventory movements table CREATE TABLE inventory_movements ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), organization_id UUID NOT NULL REFERENCES organizations(id) ON DELETE CASCADE, outlet_id UUID NOT NULL REFERENCES outlets(id) ON DELETE CASCADE, product_id UUID NOT NULL REFERENCES products(id) ON DELETE CASCADE, movement_type VARCHAR(50) NOT NULL CHECK (movement_type IN ('sale', 'purchase', 'adjustment', 'return', 'refund', 'void', 'transfer_in', 'transfer_out', 'damage', 'expiry')), quantity INTEGER NOT NULL, previous_quantity INTEGER NOT NULL, new_quantity INTEGER NOT NULL, unit_cost DECIMAL(10,2) DEFAULT 0.00, total_cost DECIMAL(10,2) DEFAULT 0.00, reference_type VARCHAR(50) CHECK (reference_type IN ('order', 'payment', 'refund', 'void', 'manual', 'transfer', 'purchase_order')), reference_id UUID, order_id UUID REFERENCES orders(id) ON DELETE SET NULL, payment_id UUID REFERENCES payments(id) ON DELETE SET NULL, user_id UUID NOT NULL REFERENCES users(id) ON DELETE RESTRICT, reason VARCHAR(255), notes TEXT, metadata JSONB DEFAULT '{}', created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Indexes CREATE INDEX idx_inventory_movements_organization_id ON inventory_movements(organization_id); CREATE INDEX idx_inventory_movements_outlet_id ON inventory_movements(outlet_id); CREATE INDEX idx_inventory_movements_product_id ON inventory_movements(product_id); CREATE INDEX idx_inventory_movements_movement_type ON inventory_movements(movement_type); CREATE INDEX idx_inventory_movements_reference_type ON inventory_movements(reference_type); CREATE INDEX idx_inventory_movements_reference_id ON inventory_movements(reference_id); CREATE INDEX idx_inventory_movements_order_id ON inventory_movements(order_id); CREATE INDEX idx_inventory_movements_payment_id ON inventory_movements(payment_id); CREATE INDEX idx_inventory_movements_user_id ON inventory_movements(user_id); CREATE INDEX idx_inventory_movements_created_at ON inventory_movements(created_at); -- Composite indexes for common queries CREATE INDEX idx_inventory_movements_outlet_product ON inventory_movements(outlet_id, product_id); CREATE INDEX idx_inventory_movements_type_date ON inventory_movements(movement_type, created_at); CREATE INDEX idx_inventory_movements_reference ON inventory_movements(reference_type, reference_id);