fix: requests, migration to create relations genres and publishers
This commit is contained in:
parent
87d63abe8d
commit
4ebcd4c470
|
@ -0,0 +1,41 @@
|
|||
CREATE TABLE IF NOT EXISTS genres (
|
||||
genre_id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(30) NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS publishers (
|
||||
publisher_id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(50) NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
INSERT INTO genres (name)
|
||||
SELECT DISTINCT genre
|
||||
FROM board_games
|
||||
WHERE genre IS NOT NULL;
|
||||
|
||||
INSERT INTO publishers (name)
|
||||
SELECT DISTINCT publisher
|
||||
FROM board_games
|
||||
WHERE publisher IS NOT NULL;
|
||||
|
||||
ALTER TABLE board_games
|
||||
ADD COLUMN genre_id INT,
|
||||
ADD COLUMN publisher_id INT;
|
||||
|
||||
UPDATE board_games
|
||||
SET genre_id = g.genre_id
|
||||
FROM genres g
|
||||
WHERE board_games.genre = g.name;
|
||||
|
||||
UPDATE board_games
|
||||
SET publisher_id = p.publisher_id
|
||||
FROM publishers p
|
||||
WHERE board_games.publisher = p.name;
|
||||
|
||||
ALTER TABLE board_games
|
||||
DROP COLUMN genre,
|
||||
DROP COLUMN publisher;
|
||||
|
||||
ALTER TABLE board_games
|
||||
ADD CONSTRAINT fk_genre FOREIGN KEY (genre_id) REFERENCES genres (genre_id),
|
||||
ADD CONSTRAINT fk_publisher FOREIGN KEY (publisher_id) REFERENCES publishers (publisher_id);
|
|
@ -0,0 +1,46 @@
|
|||
--- Зарегистрировать нового пользователя
|
||||
insert into clients (forename, surname, patronymic, age, phone_number, email)
|
||||
values ('Иван', 'Иванович', 'Иванов', 22, '+71234567890', 'test@email.com');
|
||||
|
||||
--- Вывести доступные категории настольных игр
|
||||
select name from sections;
|
||||
|
||||
--- Вывод названия игры и цена при условии что цена меньше 2000 руб (для незарегистрированного пользователя)
|
||||
set lc_monetary to 'ru_RU.UTF-8';
|
||||
select name, price
|
||||
from board_games
|
||||
where price::numeric < 2000;
|
||||
|
||||
--- Вывод самых дорогих игр с жанрами и издателями
|
||||
set lc_monetary to 'ru_RU.UTF-8';
|
||||
select
|
||||
board_games.name as name,
|
||||
genres.name as genre,
|
||||
publishers.name as publisher,
|
||||
board_games.price as price
|
||||
from
|
||||
board_games
|
||||
join genres using(genre_id)
|
||||
join publishers using(publisher_id)
|
||||
order by
|
||||
price desc
|
||||
limit 10;
|
||||
|
||||
--- Вывод количества продаж за период
|
||||
set lc_monetary to 'ru_RU.UTF-8';
|
||||
select
|
||||
board_games.name as name,
|
||||
publishers.name as publisher,
|
||||
board_games.price as price,
|
||||
sum(orders_games.count) as sells
|
||||
from
|
||||
board_games
|
||||
join publishers using(publisher_id)
|
||||
join orders_games using(board_game_id)
|
||||
join orders using(order_id)
|
||||
where
|
||||
orders.order_date BETWEEN '2024-12-16' AND '2024-12-20';
|
||||
group by
|
||||
board_games.name, publishers.name, board_games.price
|
||||
order by
|
||||
publishers.name
|
Loading…
Reference in New Issue