Skip to content
This repository was archived by the owner on Jan 1, 2026. It is now read-only.

Commit 4600e4f

Browse files
VianpyroVianpyro
andauthored
Add categories attributes tags (#9)
* Add (paginated) product querries * feat: Update database schema tests and seed data - Enhanced `schema.test.sql` to include new tables, columns, and constraints for products, categories, attributes, tags, and customization options. - Expanded test coverage to validate the existence of new tables and their relationships. - Updated `seed_data.test.sql` to include checks for new product categories, products, attributes, tags, and customization options. - Introduced new functions for product price calculation, product attributes filtering, category retrieval, product details fetching, tag retrieval, and product searching. - Added comprehensive tests for the new functions to ensure correct functionality and data retrieval. * Remove useless comments from schema test file * Clean up seed data and test files by removing unnecessary comments * Improve readability of seed data SQL by standardizing comment formatting --------- Co-authored-by: Vianpyro <[email protected]>
1 parent 55da25a commit 4600e4f

13 files changed

+1200
-133
lines changed

.vscode/settings.json

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -23,6 +23,8 @@
2323
],
2424
"sqltools.useNodeRuntime": false,
2525
"triggerTaskOnSave.tasks": {
26-
"Lint SQL File": ["database/**/*.sql"]
26+
"Lint SQL File": [
27+
"database/**/*.sql"
28+
]
2729
}
2830
}
Lines changed: 43 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,43 @@
1+
CREATE OR REPLACE FUNCTION calculate_product_price(
2+
p_product_id INTEGER,
3+
p_variant_id INTEGER DEFAULT NULL,
4+
p_customization_values INTEGER [] DEFAULT NULL
5+
) RETURNS NUMERIC(10, 2) AS $$
6+
DECLARE
7+
base_price NUMERIC(10, 2);
8+
final_price NUMERIC(10, 2);
9+
customization_total NUMERIC(10, 2) := 0;
10+
product_type_val product_type;
11+
BEGIN
12+
-- Get product type and base pricing
13+
SELECT p.product_type,
14+
CASE
15+
WHEN p.product_type = 'variant_based' AND p_variant_id IS NOT NULL THEN
16+
COALESCE(pv.price_override, p.price)
17+
WHEN p.product_type = 'configurable' THEN p.base_price
18+
ELSE p.price
19+
END
20+
INTO product_type_val, base_price
21+
FROM products p
22+
LEFT JOIN product_variants pv ON p.product_id = pv.product_id
23+
AND pv.product_variant_id = p_variant_id
24+
WHERE p.product_id = p_product_id;
25+
26+
IF base_price IS NULL THEN
27+
RAISE EXCEPTION 'Product not found or invalid configuration';
28+
END IF;
29+
30+
final_price := base_price;
31+
32+
-- Add customization costs for configurable products
33+
IF product_type_val = 'configurable' AND p_customization_values IS NOT NULL THEN
34+
SELECT COALESCE(SUM(price_modifier), 0) INTO customization_total
35+
FROM customization_option_values
36+
WHERE option_value_id = ANY(p_customization_values);
37+
38+
final_price := final_price + customization_total;
39+
END IF;
40+
41+
RETURN GREATEST(final_price, 0); -- Ensure price is never negative
42+
END;
43+
$$ LANGUAGE plpgsql;
Lines changed: 33 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,33 @@
1+
CREATE OR REPLACE FUNCTION get_product_attributes_for_filter(
2+
p_category_id INTEGER DEFAULT NULL
3+
) RETURNS TABLE (
4+
attribute_name TEXT,
5+
attribute_values JSONB
6+
) AS $$
7+
BEGIN
8+
RETURN QUERY
9+
SELECT
10+
pa.attribute_name,
11+
jsonb_agg(
12+
DISTINCT jsonb_build_object(
13+
'value', pa.attribute_value,
14+
'color', pa.attribute_color::TEXT,
15+
'count', (
16+
SELECT COUNT(DISTINCT p2.product_id)
17+
FROM product_attributes pa2
18+
JOIN products p2 ON pa2.product_id = p2.product_id
19+
WHERE pa2.attribute_name = pa.attribute_name
20+
AND pa2.attribute_value = pa.attribute_value
21+
AND p2.is_enabled = TRUE
22+
AND (p_category_id IS NULL OR p2.category_id = p_category_id)
23+
)
24+
)
25+
) as attribute_values
26+
FROM product_attributes pa
27+
JOIN products p ON pa.product_id = p.product_id
28+
WHERE p.is_enabled = TRUE
29+
AND (p_category_id IS NULL OR p.category_id = p_category_id)
30+
GROUP BY pa.attribute_name
31+
ORDER BY pa.attribute_name;
32+
END;
33+
$$ LANGUAGE plpgsql;
Lines changed: 27 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,27 @@
1+
CREATE OR REPLACE FUNCTION get_product_categories(
2+
p_language_iso CHAR(2) DEFAULT 'en'
3+
) RETURNS TABLE (
4+
category_id INTEGER,
5+
category_name TEXT,
6+
category_color TEXT,
7+
category_description TEXT,
8+
product_count BIGINT
9+
) AS $$
10+
BEGIN
11+
RETURN QUERY
12+
SELECT
13+
pc.category_id,
14+
COALESCE(ct.category_name, pc.category_name) as category_name,
15+
pc.category_color::TEXT,
16+
COALESCE(ct.category_description, pc.category_description) as category_description,
17+
COUNT(p.product_id) as product_count
18+
FROM product_categories pc
19+
LEFT JOIN category_translations ct ON pc.category_id = ct.category_id
20+
AND ct.language_id = (SELECT language_id FROM languages WHERE iso_code = p_language_iso)
21+
LEFT JOIN products p ON pc.category_id = p.category_id AND p.is_enabled = TRUE
22+
WHERE pc.is_enabled = TRUE
23+
GROUP BY pc.category_id, pc.category_name, pc.category_color, pc.category_description,
24+
ct.category_name, ct.category_description, pc.display_order
25+
ORDER BY pc.display_order, COALESCE(ct.category_name, pc.category_name);
26+
END;
27+
$$ LANGUAGE plpgsql;
Lines changed: 158 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,158 @@
1+
CREATE OR REPLACE FUNCTION get_product_details(
2+
p_product_id INTEGER,
3+
p_language_iso CHAR(2) DEFAULT 'en'
4+
) RETURNS TABLE (
5+
-- Product data
6+
product_id INTEGER,
7+
product_name TEXT,
8+
product_description TEXT,
9+
product_type PRODUCT_TYPE,
10+
price NUMERIC(10, 2),
11+
base_price NUMERIC(10, 2),
12+
image_url TEXT,
13+
preparation_time_hours INTEGER,
14+
min_order_hours INTEGER,
15+
serving_info TEXT,
16+
is_customizable BOOLEAN,
17+
created_at TIMESTAMPTZ,
18+
-- Related data
19+
category JSONB,
20+
variants JSONB,
21+
customization_options JSONB,
22+
attributes JSONB,
23+
tags JSONB,
24+
images JSONB
25+
) AS $$
26+
BEGIN
27+
RETURN QUERY
28+
SELECT
29+
p.product_id,
30+
COALESCE(tr.product_name, p.product_name) as product_name,
31+
COALESCE(tr.product_description, p.product_description) as product_description,
32+
p.product_type,
33+
p.price,
34+
p.base_price,
35+
p.image_url,
36+
p.preparation_time_hours,
37+
p.min_order_hours,
38+
p.serving_info,
39+
p.is_customizable,
40+
p.created_at,
41+
-- Category
42+
CASE WHEN p.category_id IS NOT NULL THEN
43+
jsonb_build_object(
44+
'category_id', pc.category_id,
45+
'name', COALESCE(ct.category_name, pc.category_name),
46+
'color', pc.category_color::TEXT,
47+
'description', COALESCE(ct.category_description, pc.category_description)
48+
)
49+
ELSE NULL END as category,
50+
-- Variants
51+
CASE
52+
WHEN p.product_type = 'variant_based' THEN
53+
(SELECT jsonb_agg(
54+
jsonb_build_object(
55+
'variant_id', pv.product_variant_id,
56+
'name', pv.variant_name,
57+
'quantity', pv.quantity,
58+
'price', COALESCE(pv.price_override, p.price),
59+
'serving_size', pv.serving_size,
60+
'is_default', pv.is_default,
61+
'size', pv.size
62+
) ORDER BY pv.display_order
63+
) FROM product_variants pv
64+
WHERE pv.product_id = p.product_id AND pv.is_test = FALSE)
65+
ELSE NULL
66+
END as variants,
67+
-- Customization options for configurable products
68+
CASE
69+
WHEN p.product_type = 'configurable' THEN
70+
(SELECT jsonb_agg(
71+
jsonb_build_object(
72+
'option_id', co.customization_option_id,
73+
'name', COALESCE(cot.option_name, co.option_name),
74+
'type', co.option_type,
75+
'is_required', COALESCE(pco.is_required, co.is_required),
76+
'values', CASE
77+
WHEN co.option_type IN ('single_select', 'multi_select') THEN
78+
(SELECT jsonb_agg(
79+
jsonb_build_object(
80+
'value_id', cov.option_value_id,
81+
'name', COALESCE(covt.value_name, cov.value_name),
82+
'price_modifier', cov.price_modifier,
83+
'is_default', cov.is_default
84+
) ORDER BY cov.display_order
85+
) FROM customization_option_values cov
86+
LEFT JOIN customization_option_value_translations covt
87+
ON cov.option_value_id = covt.option_value_id
88+
AND covt.language_id = (SELECT language_id FROM languages WHERE iso_code = p_language_iso)
89+
WHERE cov.customization_option_id = co.customization_option_id
90+
AND cov.is_enabled = TRUE)
91+
ELSE NULL
92+
END
93+
) ORDER BY COALESCE(pco.display_order, co.display_order)
94+
) FROM product_customization_options pco
95+
JOIN customization_options co ON pco.customization_option_id = co.customization_option_id
96+
LEFT JOIN customization_option_translations cot
97+
ON co.customization_option_id = cot.customization_option_id
98+
AND cot.language_id = (SELECT language_id FROM languages WHERE iso_code = p_language_iso)
99+
WHERE pco.product_id = p.product_id AND co.is_enabled = TRUE)
100+
ELSE NULL
101+
END as customization_options,
102+
-- Product attributes (fixed - no nested aggregates)
103+
(SELECT
104+
CASE
105+
WHEN COUNT(*) > 0 THEN
106+
jsonb_object_agg(
107+
attr_grouped.attribute_name,
108+
attr_grouped.values
109+
)
110+
ELSE NULL
111+
END
112+
FROM (
113+
SELECT
114+
pa.attribute_name,
115+
jsonb_agg(
116+
jsonb_build_object(
117+
'value', pa.attribute_value,
118+
'color', pa.attribute_color::TEXT
119+
)
120+
) as values
121+
FROM product_attributes pa
122+
WHERE pa.product_id = p.product_id
123+
GROUP BY pa.attribute_name
124+
) attr_grouped
125+
) as attributes,
126+
-- Product tags
127+
(SELECT jsonb_agg(
128+
jsonb_build_object(
129+
'tag_id', pt.product_tag_id,
130+
'name', COALESCE(ptt.tag_name, pt.tag_name),
131+
'color', pt.tag_color::TEXT,
132+
'description', COALESCE(ptt.tag_description, pt.tag_description)
133+
) ORDER BY pt.display_order
134+
) FROM product_tag_assignments pta
135+
JOIN product_tags pt ON pta.product_tag_id = pt.product_tag_id
136+
LEFT JOIN product_tag_translations ptt ON pt.product_tag_id = ptt.product_tag_id
137+
AND ptt.language_id = (SELECT language_id FROM languages WHERE iso_code = p_language_iso)
138+
WHERE pta.product_id = p.product_id AND pt.is_enabled = TRUE
139+
) as tags,
140+
-- Product images
141+
(SELECT jsonb_agg(
142+
jsonb_build_object(
143+
'image_id', pi.product_image_id,
144+
'url', pi.image_url,
145+
'is_primary', pi.is_primary,
146+
'variant_id', pi.variant_id
147+
) ORDER BY pi.is_primary DESC, pi.created_at
148+
) FROM product_images pi
149+
WHERE pi.product_id = p.product_id
150+
) as images
151+
FROM products p
152+
LEFT JOIN product_categories pc ON p.category_id = pc.category_id
153+
LEFT JOIN category_translations ct ON pc.category_id = ct.category_id
154+
AND ct.language_id = (SELECT language_id FROM languages WHERE iso_code = p_language_iso)
155+
LEFT JOIN LATERAL get_product_translation(p.product_id, p_language_iso) tr ON true
156+
WHERE p.product_id = p_product_id AND p.is_enabled = TRUE;
157+
END;
158+
$$ LANGUAGE plpgsql;
Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,28 @@
1+
CREATE OR REPLACE FUNCTION get_product_tags(
2+
p_language_iso CHAR(2) DEFAULT 'en'
3+
) RETURNS TABLE (
4+
tag_id INTEGER,
5+
tag_name TEXT,
6+
tag_color TEXT,
7+
tag_description TEXT,
8+
product_count BIGINT
9+
) AS $$
10+
BEGIN
11+
RETURN QUERY
12+
SELECT
13+
pt.product_tag_id,
14+
COALESCE(ptt.tag_name, pt.tag_name) as tag_name,
15+
pt.tag_color::TEXT,
16+
COALESCE(ptt.tag_description, pt.tag_description) as tag_description,
17+
COUNT(pta.product_id) as product_count
18+
FROM product_tags pt
19+
LEFT JOIN product_tag_translations ptt ON pt.product_tag_id = ptt.product_tag_id
20+
AND ptt.language_id = (SELECT language_id FROM languages WHERE iso_code = p_language_iso)
21+
LEFT JOIN product_tag_assignments pta ON pt.product_tag_id = pta.product_tag_id
22+
LEFT JOIN products p ON pta.product_id = p.product_id AND p.is_enabled = TRUE
23+
WHERE pt.is_enabled = TRUE
24+
GROUP BY pt.product_tag_id, pt.tag_name, pt.tag_color, pt.tag_description,
25+
ptt.tag_name, ptt.tag_description, pt.display_order
26+
ORDER BY pt.display_order, COALESCE(ptt.tag_name, pt.tag_name);
27+
END;
28+
$$ LANGUAGE plpgsql;

0 commit comments

Comments
 (0)