Simon Bruder
00d7647187
While diesel has a native rust interface, writing more complex queries is easier when you can just pass a SQL query string.
48 lines
1.6 KiB
PL/PgSQL
48 lines
1.6 KiB
PL/PgSQL
-- SPDX-FileCopyrightText: 2024 Simon Bruder <simon@sbruder.de>
|
||
--
|
||
-- SPDX-License-Identifier: AGPL-3.0-or-later
|
||
|
||
-- generic is a category of products (like CR2032 3 V battery)
|
||
-- or a product where details do not matter (like USB-A to USB-Micro-B cable 1 m)
|
||
-- specific is a concrete model of product (like Panasonic DL2032)
|
||
CREATE TYPE item_class_type AS ENUM ('generic', 'specific');
|
||
|
||
CREATE TABLE item_classes (
|
||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||
name VARCHAR NOT NULL,
|
||
type item_class_type NOT NULL DEFAULT 'generic',
|
||
parent UUID REFERENCES item_classes(id),
|
||
CONSTRAINT parent_only_for_specific CHECK (type = 'generic' AND parent IS NULL OR type = 'specific' AND parent IS NOT NULL)
|
||
);
|
||
|
||
INSERT INTO item_classes (id, name) values ('afd0e9bd-c4df-425e-8af4-6b5b0326a4ae', 'Default Item Class');
|
||
|
||
ALTER TABLE items
|
||
ADD class UUID NOT NULL REFERENCES item_classes(id) DEFAULT 'afd0e9bd-c4df-425e-8af4-6b5b0326a4ae';
|
||
ALTER TABLE items
|
||
ALTER class DROP DEFAULT;
|
||
|
||
DELETE FROM item_classes
|
||
WHERE (id = 'afd0e9bd-c4df-425e-8af4-6b5b0326a4ae'
|
||
AND NOT EXISTS (SELECT 1 FROM items WHERE class = 'afd0e9bd-c4df-425e-8af4-6b5b0326a4ae' LIMIT 1));
|
||
|
||
CREATE FUNCTION check_item_class_parent()
|
||
RETURNS TRIGGER AS $$
|
||
BEGIN
|
||
IF NEW.parent IS NULL THEN
|
||
RETURN NEW;
|
||
END IF;
|
||
|
||
IF (SELECT type FROM item_classes WHERE id = NEW.parent) = 'generic' THEN
|
||
RETURN NEW;
|
||
END IF;
|
||
|
||
RAISE EXCEPTION 'Specific item classes may only have a generic parent (to avoid recursion)';
|
||
END;
|
||
$$ LANGUAGE plpgsql;
|
||
|
||
CREATE TRIGGER prevent_item_class_recursion
|
||
BEFORE INSERT OR UPDATE ON item_classes
|
||
FOR EACH ROW
|
||
EXECUTE FUNCTION check_item_class_parent();
|