From fb182a1aec3e6212504eec670855d414879ba0bb Mon Sep 17 00:00:00 2001 From: Marcel Peterkau Date: Mon, 18 Aug 2025 21:05:59 +0200 Subject: [PATCH] updated db schema --- wishlist.sql | 165 +++++++++++++++++++++++++++------------------------ 1 file changed, 86 insertions(+), 79 deletions(-) diff --git a/wishlist.sql b/wishlist.sql index decacae..c754877 100644 --- a/wishlist.sql +++ b/wishlist.sql @@ -1,91 +1,98 @@ --- phpMyAdmin SQL Dump --- version 5.2.0 --- https://www.phpmyadmin.net/ --- --- Host: localhost --- Erstellungszeit: 04. Okt 2022 um 22:36 --- Server-Version: 10.5.15-MariaDB-0+deb11u1 --- PHP-Version: 8.0.22 +-- ============================================================ +-- Simple Wishlist – Minimal-Schema +-- Tested on MariaDB 10.x / MySQL 8.x +-- ============================================================ -SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; -START TRANSACTION; -SET time_zone = "+00:00"; +/* 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`; -/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; -/*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; -/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */; -/*!40101 SET NAMES utf8mb4 */; - --- --- Datenbank: `wishlist` --- - --- -------------------------------------------------------- - --- --- Tabellenstruktur für Tabelle `lists` --- - +-- ------------------------------------------------------------ +-- LISTEN (Metadaten & Admin-Passwort) +-- ------------------------------------------------------------ CREATE TABLE `lists` ( - `ID` int(11) NOT NULL, - `title` varchar(255) NOT NULL, - `description` text NOT NULL, - `edit_pw` varchar(64) NOT NULL -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; - --- -------------------------------------------------------- - --- --- Tabellenstruktur für Tabelle `wishes` --- + `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, - `wishlist` int(11) NOT NULL DEFAULT 0, - `title` varchar(128) NOT NULL, - `description` text NOT NULL, - `link` text NOT NULL, - `image` text NOT NULL, - `price` int(11) NOT NULL, - `reserved` tinyint(1) NOT NULL DEFAULT 0, - `pass_hash` varchar(64) NOT NULL DEFAULT '', - `date` date NOT NULL DEFAULT current_timestamp() -) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4; + `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 --- --- Indizes der exportierten Tabellen --- + 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; --- --- Indizes für die Tabelle `lists` --- -ALTER TABLE `lists` - ADD PRIMARY KEY (`ID`); +-- ------------------------------------------------------------ +-- 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; --- --- Indizes für die Tabelle `wishes` --- -ALTER TABLE `wishes` - ADD PRIMARY KEY (`ID`); +-- ------------------------------------------------------------ +-- 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; --- --- AUTO_INCREMENT für exportierte Tabellen --- +-- ------------------------------------------------------------ +-- 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`); --- --- AUTO_INCREMENT für Tabelle `lists` --- -ALTER TABLE `lists` - MODIFY `ID` int(11) NOT NULL AUTO_INCREMENT; +-- Wenn oft nach Datum sortiert/gefiltert wird: +CREATE INDEX `idx_wishes_wishlist_date` ON `wishes` (`wishlist`, `date`); --- --- AUTO_INCREMENT für Tabelle `wishes` --- -ALTER TABLE `wishes` - MODIFY `ID` int(11) NOT NULL AUTO_INCREMENT; -COMMIT; - -/*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; -/*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */; -/*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */; +-- Fertig.