Files
Simple-Wishlist/wishlist.sql
2025-08-18 21:05:59 +02:00

99 lines
4.0 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- ============================================================
-- Simple Wishlist Minimal-Schema
-- Tested on MariaDB 10.x / MySQL 8.x
-- ============================================================
/* Optional: eigene DB anlegen/verwenden
CREATE DATABASE IF NOT EXISTS `wishlist`
DEFAULT CHARACTER SET utf8mb4
COLLATE utf8mb4_unicode_ci;
USE `wishlist`;
*/
-- ------------------------------------------------------------
-- Tabellen löschen (idempotent für wiederholte Importe)
-- ------------------------------------------------------------
DROP TABLE IF EXISTS `wishes_reservations`;
DROP TABLE IF EXISTS `wishes`;
DROP TABLE IF EXISTS `lists`;
-- ------------------------------------------------------------
-- LISTEN (Metadaten & Admin-Passwort)
-- ------------------------------------------------------------
CREATE TABLE `lists` (
`ID` INT(11) NOT NULL AUTO_INCREMENT,
`uuid` CHAR(36) NOT NULL, -- öffentliche, stabile ID (Links)
`title` VARCHAR(255) NOT NULL,
`description` TEXT NOT NULL,
`edit_pw` VARCHAR(255) NOT NULL, -- Passwort-Hash (password_hash)
PRIMARY KEY (`ID`),
UNIQUE KEY `uq_lists_uuid` (`uuid`)
) ENGINE=InnoDB
DEFAULT CHARSET = utf8mb4
COLLATE = utf8mb4_unicode_ci;
-- ------------------------------------------------------------
-- WÜNSCHE (einer Liste zugeordnet)
-- ------------------------------------------------------------
CREATE TABLE `wishes` (
`ID` INT(11) NOT NULL AUTO_INCREMENT,
`wishlist` INT(11) NOT NULL, -- FK -> lists.ID
`title` VARCHAR(128) NOT NULL,
`description` TEXT NOT NULL,
`link` TEXT NOT NULL, -- optionaler Anbieter-Link (leer erlaubt)
`image` TEXT DEFAULT NULL, -- Dateiname (lokal) oder NULL
`price` INT(11) NOT NULL DEFAULT 0, -- Preis in Cent
`date` DATE NOT NULL DEFAULT (CURRENT_DATE),
`priority` INT(11) NOT NULL DEFAULT 0, -- Sortierung (höher = weiter oben)
`qty` INT(11) NOT NULL DEFAULT 1, -- Anzahl benötigter Exemplare
PRIMARY KEY (`ID`),
KEY `idx_wishes_wishlist` (`wishlist`),
CONSTRAINT `fk_wishes_list`
FOREIGN KEY (`wishlist`) REFERENCES `lists` (`ID`)
ON DELETE CASCADE
) ENGINE=InnoDB
DEFAULT CHARSET = utf8mb4
COLLATE = utf8mb4_unicode_ci;
-- ------------------------------------------------------------
-- RESERVIERUNGEN (pro Wunsch mehrere Einträge, je Reservierung einer)
-- ------------------------------------------------------------
CREATE TABLE `wishes_reservations` (
`id` INT(11) NOT NULL AUTO_INCREMENT,
`wish_id` INT(11) NOT NULL, -- FK -> wishes.ID
`pass_hash` VARCHAR(255) NOT NULL, -- Passwort-Hash (password_hash)
`created_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY (`id`),
KEY `idx_wr_wish` (`wish_id`),
CONSTRAINT `fk_wr_wish`
FOREIGN KEY (`wish_id`) REFERENCES `wishes` (`ID`)
ON DELETE CASCADE
) ENGINE=InnoDB
DEFAULT CHARSET = utf8mb4
COLLATE = utf8mb4_unicode_ci;
-- ------------------------------------------------------------
-- OPTIONALE HILFS-VIEW: reserved_count je Wunsch
-- Erleichtert das Rendern (Badge/Buttons) ohne Subquery im Code.
-- Nutzung: SELECT w.*, rc.reserved_count FROM wishes w
-- LEFT JOIN v_wish_reserved_counts rc ON rc.wish_id = w.ID
-- ------------------------------------------------------------
CREATE OR REPLACE VIEW `v_wish_reserved_counts` AS
SELECT
wr.wish_id,
COUNT(*) AS reserved_count
FROM wishes_reservations wr
GROUP BY wr.wish_id;
-- ------------------------------------------------------------
-- EMPFOHLENE INDIZES (optional je nach Abfragen)
-- ------------------------------------------------------------
-- Wenn häufig nach (wishlist, priority DESC) sortiert wird:
CREATE INDEX `idx_wishes_wishlist_priority` ON `wishes` (`wishlist`, `priority`);
-- Wenn oft nach Datum sortiert/gefiltert wird:
CREATE INDEX `idx_wishes_wishlist_date` ON `wishes` (`wishlist`, `date`);
-- Fertig.