updated db schema
This commit is contained in:
165
wishlist.sql
165
wishlist.sql
@@ -1,91 +1,98 @@
|
|||||||
-- phpMyAdmin SQL Dump
|
-- ============================================================
|
||||||
-- version 5.2.0
|
-- Simple Wishlist – Minimal-Schema
|
||||||
-- https://www.phpmyadmin.net/
|
-- Tested on MariaDB 10.x / MySQL 8.x
|
||||||
--
|
-- ============================================================
|
||||||
-- Host: localhost
|
|
||||||
-- Erstellungszeit: 04. Okt 2022 um 22:36
|
|
||||||
-- Server-Version: 10.5.15-MariaDB-0+deb11u1
|
|
||||||
-- PHP-Version: 8.0.22
|
|
||||||
|
|
||||||
SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO";
|
/* Optional: eigene DB anlegen/verwenden
|
||||||
START TRANSACTION;
|
CREATE DATABASE IF NOT EXISTS `wishlist`
|
||||||
SET time_zone = "+00:00";
|
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 */;
|
-- LISTEN (Metadaten & Admin-Passwort)
|
||||||
/*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */;
|
-- ------------------------------------------------------------
|
||||||
/*!40101 SET NAMES utf8mb4 */;
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Datenbank: `wishlist`
|
|
||||||
--
|
|
||||||
|
|
||||||
-- --------------------------------------------------------
|
|
||||||
|
|
||||||
--
|
|
||||||
-- Tabellenstruktur für Tabelle `lists`
|
|
||||||
--
|
|
||||||
|
|
||||||
CREATE TABLE `lists` (
|
CREATE TABLE `lists` (
|
||||||
`ID` int(11) NOT NULL,
|
`ID` INT(11) NOT NULL AUTO_INCREMENT,
|
||||||
`title` varchar(255) NOT NULL,
|
`uuid` CHAR(36) NOT NULL, -- öffentliche, stabile ID (Links)
|
||||||
`description` text NOT NULL,
|
`title` VARCHAR(255) NOT NULL,
|
||||||
`edit_pw` varchar(64) NOT NULL
|
`description` TEXT NOT NULL,
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
`edit_pw` VARCHAR(255) NOT NULL, -- Passwort-Hash (password_hash)
|
||||||
|
PRIMARY KEY (`ID`),
|
||||||
-- --------------------------------------------------------
|
UNIQUE KEY `uq_lists_uuid` (`uuid`)
|
||||||
|
) ENGINE=InnoDB
|
||||||
--
|
DEFAULT CHARSET = utf8mb4
|
||||||
-- Tabellenstruktur für Tabelle `wishes`
|
COLLATE = utf8mb4_unicode_ci;
|
||||||
--
|
|
||||||
|
|
||||||
|
-- ------------------------------------------------------------
|
||||||
|
-- WÜNSCHE (einer Liste zugeordnet)
|
||||||
|
-- ------------------------------------------------------------
|
||||||
CREATE TABLE `wishes` (
|
CREATE TABLE `wishes` (
|
||||||
`ID` int(11) NOT NULL,
|
`ID` INT(11) NOT NULL AUTO_INCREMENT,
|
||||||
`wishlist` int(11) NOT NULL DEFAULT 0,
|
`wishlist` INT(11) NOT NULL, -- FK -> lists.ID
|
||||||
`title` varchar(128) NOT NULL,
|
`title` VARCHAR(128) NOT NULL,
|
||||||
`description` text NOT NULL,
|
`description` TEXT NOT NULL,
|
||||||
`link` text NOT NULL,
|
`link` TEXT NOT NULL, -- optionaler Anbieter-Link (leer erlaubt)
|
||||||
`image` text NOT NULL,
|
`image` TEXT DEFAULT NULL, -- Dateiname (lokal) oder NULL
|
||||||
`price` int(11) NOT NULL,
|
`price` INT(11) NOT NULL DEFAULT 0, -- Preis in Cent
|
||||||
`reserved` tinyint(1) NOT NULL DEFAULT 0,
|
`date` DATE NOT NULL DEFAULT (CURRENT_DATE),
|
||||||
`pass_hash` varchar(64) NOT NULL DEFAULT '',
|
`priority` INT(11) NOT NULL DEFAULT 0, -- Sortierung (höher = weiter oben)
|
||||||
`date` date NOT NULL DEFAULT current_timestamp()
|
`qty` INT(11) NOT NULL DEFAULT 1, -- Anzahl benötigter Exemplare
|
||||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
|
|
||||||
|
|
||||||
--
|
PRIMARY KEY (`ID`),
|
||||||
-- Indizes der exportierten Tabellen
|
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`
|
-- RESERVIERUNGEN (pro Wunsch mehrere Einträge, je Reservierung einer)
|
||||||
--
|
-- ------------------------------------------------------------
|
||||||
ALTER TABLE `lists`
|
CREATE TABLE `wishes_reservations` (
|
||||||
ADD PRIMARY KEY (`ID`);
|
`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`
|
-- OPTIONALE HILFS-VIEW: reserved_count je Wunsch
|
||||||
--
|
-- Erleichtert das Rendern (Badge/Buttons) ohne Subquery im Code.
|
||||||
ALTER TABLE `wishes`
|
-- Nutzung: SELECT w.*, rc.reserved_count FROM wishes w
|
||||||
ADD PRIMARY KEY (`ID`);
|
-- 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`);
|
||||||
|
|
||||||
--
|
-- Wenn oft nach Datum sortiert/gefiltert wird:
|
||||||
-- AUTO_INCREMENT für Tabelle `lists`
|
CREATE INDEX `idx_wishes_wishlist_date` ON `wishes` (`wishlist`, `date`);
|
||||||
--
|
|
||||||
ALTER TABLE `lists`
|
|
||||||
MODIFY `ID` int(11) NOT NULL AUTO_INCREMENT;
|
|
||||||
|
|
||||||
--
|
-- Fertig.
|
||||||
-- 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 */;
|
|
||||||
|
Reference in New Issue
Block a user