Commit 1d912239 by Patryk Czarnik

Definicja bazy danych sklep

parent aedfe3ac
DROP TABLE IF EXISTS order_products;
DROP TABLE IF EXISTS orders;
DROP TABLE IF EXISTS customers;
DROP TABLE IF EXISTS products;
DROP SEQUENCE IF EXISTS products_seq;
DROP SEQUENCE IF EXISTS orders_seq;
DROP TYPE IF EXISTS order_status;
CREATE SEQUENCE products_seq START 10;
CREATE SEQUENCE orders_seq START 10;
CREATE TABLE products (
product_id INTEGER DEFAULT nextval('products_seq'),
product_name VARCHAR(100) NOT NULL,
-- 10 cyfr, z czego 2 po prawej stronie kropki
-- zakres wartości od -99999999.99 do +99999999.99
-- inna nazwa: DECIMAL, w Oraclu nazwa NUMBER
price NUMERIC(10, 2) NOT NULL,
vat NUMERIC(2, 2), -- wartości do 0.99
description TEXT, -- w Oraclu pod nazwą CLOB
PRIMARY KEY(product_id),
CHECK (price > 0),
CHECK (vat >= 0),
CHECK (length(product_name) > 0)
);
-- Nie zawsze kluczem głównym jest automatycznie generowany numer.
-- Kluczem może być też kolumna tekstowa, albo typu "data z czasem" (timestamp).
-- Przykładowo tutaj napiszemy, że kluczem klienta jest jego email.
CREATE TABLE customers (
customer_email VARCHAR(100),
customer_name VARCHAR(100) NOT NULL,
phone_number VARCHAR(20),
address VARCHAR(250),
postal_code VARCHAR(10),
city VARCHAR(100),
PRIMARY KEY(customer_email)
);
CREATE TYPE order_status AS ENUM (
'NEW',
'CONFIRMED',
'PAID',
'SHIPPED',
'DELIVERED',
'CLOSED',
'RETURNED'
);
CREATE TABLE orders (
order_id INTEGER DEFAULT nextval('orders_seq') ,
customer_email VARCHAR(100) NOT NULL,
status order_status DEFAULT 'NEW' NOT NULL,
order_date TIMESTAMP DEFAULT current_timestamp NOT NULL,
delivery_date DATE,
PRIMARY KEY(order_id),
FOREIGN KEY(customer_email) REFERENCES customers(customer_email),
-- kolumna customer_email z tej tabeli wskazuje na kolumnę customer_email z tabeli customers
-- (można wpisać tylko email istniejącego klienta)
CHECK (delivery_date >= order_date::DATE)
);
CREATE TABLE order_products (
order_id INTEGER NOT NULL,
product_id INTEGER NOT NULL,
quantity SMALLINT DEFAULT 1 NOT NULL,
actual_price NUMERIC(10, 2) NOT NULL,
actual_vat NUMERIC(2, 2),
PRIMARY KEY(order_id, product_id),
FOREIGN KEY(order_id) REFERENCES orders(order_id),
FOREIGN KEY(product_id) REFERENCES products(product_id)
);
INSERT INTO products(product_id, product_name, price, vat, description)
VALUES (1, 'pralka', 2900.00, 0.23, 'Pralka szybkoobrotowa');
INSERT INTO products(product_id, product_name, price, vat, description)
VALUES (2, 'odkurzacz', 800.00, 0.23, 'Odkurzacz automatyczny');
INSERT INTO products(product_id, product_name, price, vat, description)
VALUES (3, 'telewizor 55"', 3300.00, 0.23, 'Telewizor 55 cali 4K');
INSERT INTO products(product_id, product_name, price, vat, description)
VALUES (4, 'telewizor 40"', 2200.00, 0.23, 'Telewizor 40 Full HD');
INSERT INTO products(product_id, product_name, price, vat)
VALUES (5, 'myszka gejmerska', 444.00, 0.23);
INSERT INTO customers(customer_email, phone_number, customer_name, address, postal_code, city)
VALUES ('ala@example.com', '123123123', 'Ala Kowalska', 'Jasna 14/16', '01-234', 'Warszawa');
INSERT INTO customers(customer_email, phone_number, customer_name, address, postal_code, city)
VALUES ('ola@example.com', '321321321', 'Ola Malinowska', 'Ciemna 133', '99-999', 'Pcim');
INSERT INTO orders(order_id, customer_email, order_date, status)
VALUES (1, 'ala@example.com', '2021-11-20 12:30:00', 'PAID');
INSERT INTO orders(order_id, customer_email, order_date, status, delivery_date)
VALUES (2, 'ola@example.com', '2021-11-18 10:00:00', 'SHIPPED', '2021-12-01');
INSERT INTO orders(order_id, customer_email)
VALUES (3, 'ala@example.com');
INSERT INTO order_products(order_id, product_id, quantity, actual_price, actual_vat)
VALUES (1, 1, 1, 2900.00, 0.23);
INSERT INTO order_products(order_id, product_id, quantity, actual_price, actual_vat)
VALUES (1, 2, 3, 2400.00, 0.23);
INSERT INTO order_products(order_id, product_id, quantity, actual_price, actual_vat)
VALUES (2, 2, 1, 800.00, 0.23);
INSERT INTO order_products(order_id, product_id, quantity, actual_price, actual_vat)
VALUES (3, 4, 1, 2200.00, 0.23);
INSERT INTO order_products(order_id, product_id, quantity, actual_price, actual_vat)
VALUES (3, 3, 1, 300.00, 0.23);
INSERT INTO order_products(order_id, product_id, quantity, actual_price, actual_vat)
VALUES (3, 5, 1, 1000.00, 0.23);
-- SELECT * FROM products;
-- SELECT * FROM orders FULL JOIN customers USING(customer_email);
-- SELECT * FROM orders LEFT JOIN customers USING(customer_email) LEFT JOIN order_products USING(order_id) LEFT JOIN products USING(product_id) ORDER BY order_id, product_id;
DROP TABLE IF EXISTS order_products;
DROP TABLE IF EXISTS orders;
DROP TABLE IF EXISTS customers;
DROP TABLE IF EXISTS products;
CREATE TABLE products (
product_id SERIAL PRIMARY KEY,
product_name VARCHAR(100) NOT NULL,
-- 10 cyfr, z czego 2 po prawej stronie kropki
-- zakres wartości od -99999999.99 do +99999999.99
-- inna nazwa: DECIMAL, w Oraclu nazwa NUMBER
price NUMERIC(10, 2) NOT NULL,
vat NUMERIC(2, 2), -- wartości do 0.99
description TEXT -- w Oraclu pod nazwą CLOB
);
-- Nie zawsze kluczem głównym jest automatycznie generowany numer.
-- Kluczem może być też kolumna tekstowa, albo typu "data z czasem" (timestamp).
-- Przykładowo tutaj napiszemy, że kluczem klienta jest jego email.
CREATE TABLE customers (
customer_email VARCHAR(100) PRIMARY KEY,
customer_name VARCHAR(100) NOT NULL,
phone_number VARCHAR(20),
address VARCHAR(250),
postal_code VARCHAR(10),
city VARCHAR(100)
);
CREATE TABLE orders (
order_id SERIAL PRIMARY KEY,
customer_email VARCHAR(100) NOT NULL REFERENCES customers(customer_email),
status VARCHAR(20) NOT NULL,
order_date TIMESTAMP NOT NULL,
delivery_date DATE
);
CREATE TABLE order_products (
order_id INTEGER NOT NULL REFERENCES orders(order_id),
product_id INTEGER NOT NULL REFERENCES products(product_id),
quantity SMALLINT NOT NULL,
actual_price NUMERIC(10, 2) NOT NULL,
actual_vat NUMERIC(2, 2),
PRIMARY KEY(order_id, product_id)
);
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment