database fixes due to adding foreign keys and seed script improvement
This commit is contained in:
@@ -178,6 +178,38 @@ CREATE TABLE IF NOT EXISTS public.user_watched_items (
|
||||
COMMENT ON TABLE public.user_watched_items IS 'A linking table that represents a user''s personal watchlist of grocery items.';
|
||||
CREATE INDEX IF NOT EXISTS idx_user_watched_items_master_item_id ON public.user_watched_items(master_item_id);
|
||||
|
||||
-- 23. Store brand information. (Moved up due to dependency in flyer_items)
|
||||
CREATE TABLE IF NOT EXISTS public.brands (
|
||||
brand_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
logo_url TEXT,
|
||||
store_id BIGINT REFERENCES public.stores(store_id) ON DELETE SET NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.brands IS 'Stores brand names like "Coca-Cola", "Maple Leaf", or "Kraft".';
|
||||
COMMENT ON COLUMN public.brands.store_id IS 'If this is a store-specific brand (e.g., President''s Choice), this links to the parent store.';
|
||||
|
||||
-- 24. For specific products, linking a master item with a brand and size. (Moved up due to dependency in flyer_items)
|
||||
CREATE TABLE IF NOT EXISTS public.products (
|
||||
product_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE,
|
||||
brand_id BIGINT REFERENCES public.brands(brand_id) ON DELETE SET NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
size TEXT,
|
||||
upc_code TEXT UNIQUE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.products IS 'Represents a specific, sellable product, combining a generic item with a brand and size.';
|
||||
COMMENT ON COLUMN public.products.upc_code IS 'Universal Product Code, if available, for exact product matching.';
|
||||
COMMENT ON COLUMN public.products.brand_id IS 'Can be null for generic/store-brand items.';
|
||||
COMMENT ON COLUMN public.products.name IS 'Prime Raised without Antibiotics Chicken Breast.';
|
||||
COMMENT ON COLUMN public.products.size IS 'e.g., "4L", "500g".';
|
||||
CREATE INDEX IF NOT EXISTS idx_products_master_item_id ON public.products(master_item_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_products_brand_id ON public.products(brand_id);
|
||||
|
||||
-- 9. The 'flyer_items' table. This stores individual items from flyers.
|
||||
CREATE TABLE IF NOT EXISTS public.flyer_items (
|
||||
flyer_item_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
@@ -424,38 +456,6 @@ COMMENT ON TABLE public.unmatched_flyer_items IS 'A queue for reviewing flyer it
|
||||
CREATE INDEX IF NOT EXISTS idx_unmatched_flyer_items_flyer_item_id ON public.unmatched_flyer_items(flyer_item_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_unmatched_flyer_items_pending ON public.unmatched_flyer_items (created_at) WHERE status = 'pending';
|
||||
|
||||
-- 23. Store brand information.
|
||||
CREATE TABLE IF NOT EXISTS public.brands (
|
||||
brand_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
logo_url TEXT,
|
||||
store_id BIGINT REFERENCES public.stores(store_id) ON DELETE SET NULL,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.brands IS 'Stores brand names like "Coca-Cola", "Maple Leaf", or "Kraft".';
|
||||
COMMENT ON COLUMN public.brands.store_id IS 'If this is a store-specific brand (e.g., President''s Choice), this links to the parent store.';
|
||||
|
||||
-- 24. For specific products, linking a master item with a brand and size.
|
||||
CREATE TABLE IF NOT EXISTS public.products (
|
||||
product_id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
master_item_id BIGINT NOT NULL REFERENCES public.master_grocery_items(master_grocery_item_id) ON DELETE CASCADE,
|
||||
brand_id BIGINT REFERENCES public.brands(brand_id) ON DELETE SET NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
size TEXT,
|
||||
upc_code TEXT UNIQUE,
|
||||
created_at TIMESTAMPTZ DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMPTZ DEFAULT now() NOT NULL
|
||||
);
|
||||
COMMENT ON TABLE public.products IS 'Represents a specific, sellable product, combining a generic item with a brand and size.';
|
||||
COMMENT ON COLUMN public.products.upc_code IS 'Universal Product Code, if available, for exact product matching.';
|
||||
COMMENT ON COLUMN public.products.brand_id IS 'Can be null for generic/store-brand items.';
|
||||
COMMENT ON COLUMN public.products.name IS 'Prime Raised without Antibiotics Chicken Breast.';
|
||||
COMMENT ON COLUMN public.products.size IS 'e.g., "4L", "500g".';
|
||||
CREATE INDEX IF NOT EXISTS idx_products_master_item_id ON public.products(master_item_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_products_brand_id ON public.products(brand_id);
|
||||
|
||||
-- 25. Linking table for when one flyer is valid for multiple locations.
|
||||
CREATE TABLE IF NOT EXISTS public.flyer_locations (
|
||||
flyer_id BIGINT NOT NULL REFERENCES public.flyers(flyer_id) ON DELETE CASCADE,
|
||||
@@ -2128,11 +2128,61 @@ DROP FUNCTION IF EXISTS public.fork_recipe(UUID, BIGINT);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.fork_recipe(p_user_id UUID, p_original_recipe_id BIGINT)
|
||||
RETURNS SETOF public.recipes
|
||||
LANGUAGE sql
|
||||
LANGUAGE plpgsql
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
-- The entire forking logic is now encapsulated in a single, atomic database function.
|
||||
SELECT * FROM public.fork_recipe(p_user_id, p_original_recipe_id);
|
||||
DECLARE
|
||||
new_recipe_id BIGINT;
|
||||
BEGIN
|
||||
-- 1. Create a copy of the recipe, linking it to the new user and the original recipe.
|
||||
INSERT INTO public.recipes (
|
||||
user_id,
|
||||
original_recipe_id,
|
||||
name,
|
||||
description,
|
||||
instructions,
|
||||
prep_time_minutes,
|
||||
cook_time_minutes,
|
||||
servings,
|
||||
photo_url,
|
||||
calories_per_serving,
|
||||
protein_grams,
|
||||
fat_grams,
|
||||
carb_grams,
|
||||
status -- Forked recipes should be private by default
|
||||
)
|
||||
SELECT
|
||||
p_user_id,
|
||||
p_original_recipe_id,
|
||||
original.name || ' (Fork)', -- Append '(Fork)' to distinguish it
|
||||
original.description,
|
||||
original.instructions,
|
||||
original.prep_time_minutes,
|
||||
original.cook_time_minutes,
|
||||
original.servings,
|
||||
original.photo_url,
|
||||
original.calories_per_serving,
|
||||
original.protein_grams,
|
||||
original.fat_grams,
|
||||
original.carb_grams,
|
||||
'private'
|
||||
FROM public.recipes AS original
|
||||
WHERE original.recipe_id = p_original_recipe_id
|
||||
RETURNING recipe_id INTO new_recipe_id;
|
||||
|
||||
-- If the original recipe didn't exist, new_recipe_id will be null.
|
||||
IF new_recipe_id IS NULL THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- 2. Copy all ingredients, tags, and appliances from the original recipe to the new one.
|
||||
INSERT INTO public.recipe_ingredients (recipe_id, master_item_id, quantity, unit) SELECT new_recipe_id, master_item_id, quantity, unit FROM public.recipe_ingredients WHERE recipe_id = p_original_recipe_id;
|
||||
INSERT INTO public.recipe_tags (recipe_id, tag_id) SELECT new_recipe_id, tag_id FROM public.recipe_tags WHERE recipe_id = p_original_recipe_id;
|
||||
INSERT INTO public.recipe_appliances (recipe_id, appliance_id) SELECT new_recipe_id, appliance_id FROM public.recipe_appliances WHERE recipe_id = p_original_recipe_id;
|
||||
|
||||
-- 3. Return the newly created recipe record.
|
||||
RETURN QUERY SELECT * FROM public.recipes WHERE recipe_id = new_recipe_id;
|
||||
END;
|
||||
$$;
|
||||
|
||||
|
||||
|
||||
Reference in New Issue
Block a user