create database shop; use shop; create table user( id int primary key auto_increment, username varchar(64) not null unique, displayname varchar(64) not null, email varchar(64) not null unique, password varchar(60) not null, role_id int not null default 1, creation_date timestamp default current_timestamp, foreign key (role_id) references user_role(id) ) auto_increment = 23001; create table user_role( id int primary key auto_increment, role varchar(32) not null unique ); insert into user_role(role) values ('normal') insert into user_role(role) values ('admin') create table user_statistics( id int primary key, total_gains decimal(6,2) not null default 0.00, sell_count int not null default 0, total_spent decimal(6,2) not null default 0.00, purchase_count int not null default 0, foreign key (id) references user(id) ); create table product( id int primary key auto_increment, seller_id int not null, name varchar(32) not null, price_pc decimal(6,2) not null, image blob not null, image_name varchar(64), foreign key (seller_id) references user(id) ); create table cart( id int primary key, price_total decimal(6,2) not null default 0.00, item_count int not null default 0, foreign key (id) references user(id) ); create table cart_item( id int primary key auto_increment, cart_id int not null, product_id int not null, count int not null, price_subtotal decimal(6,2) not null, date_added datetime default current_timestamp, foreign key (cart_id) references cart(id), foreign key (product_id) references product(id) ); create table purchase( id int primary key auto_increment, user_id int not null, purchase_time datetime default current_timestamp, price_total decimal(6,2) not null, was_successful tinyint(1) not null, foreign key (user_id) references user(id) ); create table purchase_item( id int primary key auto_increment, purchase_id int not null, product_id int not null, count int not null, price_subtotal decimal(6,2) not null, foreign key (purchase_id) references purchase(id), foreign key (product_id) references product(id) ); delimiter // create trigger after_user_insert after insert on user for each row begin insert into user_statistics(id) values (new.id); insert into cart(id) values (new.id); end; // delimiter; delimiter // create trigger after_user_delete after delete on user for each row begin delete from user_statistics where id = old.id; delete from cart where id = old.id; end; // delimiter; delimiter // create trigger after_cart_insert after insert on cart_item for each row begin update cart set price_total = ( select sum(price_subtotal) from cart_item where cart_id = new.cart_id ) where id = new.cart_id; end; // delimiter; delimiter // create trigger after_cart_delete after delete on cart_item for each row begin update cart set price_total = ifnull( (select sum(price_subtotal) from cart_item where cart_id = old.cart_id), 0.00 ) where id = old.cart_id; end; // delimiter; delimiter // create trigger calculate_price_subtotal before insert on cart_item for each row begin set new.price_subtotal = ( select new.count * p.price_pc from product p where p.id = new.product_id ); end; // delimiter;