@ -0,0 +1,360 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
Create new tables into the database | |||
Table creation order: follow primary & foreign key relations | |||
Primary keys must exist before adding linked foreign keys | |||
NOTE: | |||
- Does not create indexing for tables | |||
- Does not define ENGINE | |||
- Requires MariaDB >= 10.2 (for CHECK constraints) | |||
- Tested with MariaDB 10.3.14 | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Create new database if needed | |||
CREATE SCHEMA IF NOT EXISTS tournament_db; | |||
-- ----------------------------------------------------- | |||
-- Use the new database | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
-- Create new table COUNTRY | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS COUNTRY ( | |||
id CHAR(2) NOT NULL UNIQUE, | |||
name NVARCHAR(20) NOT NULL, | |||
PRIMARY KEY (id) | |||
); | |||
-- CREATE UNIQUE INDEX `COUNTRY.id.IDX_UNIQUE` ON COUNTRY (id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table CITY | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS CITY ( | |||
postalcode VARCHAR(10) NOT NULL, | |||
country_id CHAR(2) NOT NULL, | |||
name NVARCHAR(100) NOT NULL, | |||
PRIMARY KEY (postalcode, country_id), | |||
-- CONSTRAINT `FK1.CITY` | |||
FOREIGN KEY (country_id) | |||
REFERENCES COUNTRY (id) | |||
); | |||
-- CREATE INDEX `FK1.CITY.IDX` ON CITY (country_id ASC); | |||
-- CREATE UNIQUE INDEX `CITY.postalcode.IDX_UNIQUE` ON CITY (postalcode ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table TEAM | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS TEAM ( | |||
id CHAR(4) NOT NULL UNIQUE, | |||
name NVARCHAR(50) NOT NULL, | |||
email NVARCHAR(200) NOT NULL, | |||
phone VARCHAR(25) NULL, | |||
postalcode VARCHAR(10) NULL, | |||
street NVARCHAR(80) NULL, | |||
housenumber NVARCHAR(7) NULL, | |||
IBAN VARCHAR(30) NULL, | |||
SWIFT_bank VARCHAR(15) NULL, | |||
SWIFT_number VARCHAR(20) NULL, | |||
PRIMARY KEY (id), | |||
-- CONSTRAINT `FK1.TEAM` | |||
FOREIGN KEY (postalcode) | |||
REFERENCES CITY (postalcode) | |||
); | |||
-- CREATE INDEX `FK1.TEAM.IDX` ON TEAM (postalcode ASC); | |||
-- CREATE UNIQUE INDEX `TEAM.id.IDX_UNIQUE` ON TEAM (id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table PLAYER | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS PLAYER ( | |||
id CHAR(4) NOT NULL UNIQUE, | |||
team_id CHAR(4) NOT NULL, | |||
firstname NVARCHAR(30) NOT NULL, | |||
lastname NVARCHAR(30) NOT NULL, | |||
email NVARCHAR(200) NULL, | |||
phone VARCHAR(25) NULL, | |||
postalcode VARCHAR(10) NULL, | |||
street NVARCHAR(80) NULL, | |||
housenumber NVARCHAR(7) NULL, | |||
PRIMARY KEY (id), | |||
-- CONSTRAINT `FK2.PLAYER` | |||
FOREIGN KEY (postalcode) | |||
REFERENCES CITY (postalcode), | |||
-- CONSTRAINT `FK1.PLAYER` | |||
FOREIGN KEY (team_id) | |||
REFERENCES TEAM (id) | |||
); | |||
-- CREATE INDEX `FK1.PLAYER.IDX` ON PLAYER (postalcode ASC); | |||
-- CREATE INDEX `FK2.PLAYER.IDX` ON PLAYER (team_id ASC); | |||
-- CREATE UNIQUE INDEX `PLAYER.id.IDX_UNIQUE` ON PLAYER (id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table ORGANIZER_ORG | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS ORGANIZER_ORG ( | |||
id CHAR(4) NOT NULL UNIQUE, | |||
name NVARCHAR(50) NOT NULL, | |||
email NVARCHAR(200) NULL, | |||
phone VARCHAR(25) NULL, | |||
postalcode VARCHAR(10) NULL, | |||
street NVARCHAR(80) NULL, | |||
housenumber NVARCHAR(7) NULL, | |||
PRIMARY KEY (id), | |||
-- CONSTRAINT `FK1.ORGANIZER_ORG` | |||
FOREIGN KEY (postalcode) | |||
REFERENCES CITY (postalcode) | |||
); | |||
-- CREATE INDEX `FK1.ORGANIZER_ORG.IDX` ON ORGANIZER_ORG (postalcode ASC); | |||
-- CREATE UNIQUE INDEX `ORGANIZER_ORG.id.IDX_UNIQUE` ON ORGANIZER_ORG (id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table ORG_EMPLOYEE | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS ORG_EMPLOYEE ( | |||
id CHAR(4) NOT NULL UNIQUE, | |||
organizer_org_id CHAR(4) NOT NULL, | |||
firstname NVARCHAR(30) NOT NULL, | |||
lastname NVARCHAR(30) NOT NULL, | |||
email NVARCHAR(200) NULL, | |||
phone VARCHAR(25) NULL, | |||
postalcode VARCHAR(10) NULL, | |||
street NVARCHAR(80) NULL, | |||
housenumber NVARCHAR(7) NULL, | |||
PRIMARY KEY (id), | |||
-- CONSTRAINT `FK2.ORG_EMPLOYEE` | |||
FOREIGN KEY (postalcode) | |||
REFERENCES CITY (postalcode), | |||
-- CONSTRAINT `FK1.ORG_EMPLOYEE` | |||
FOREIGN KEY (organizer_org_id) | |||
REFERENCES ORGANIZER_ORG (id) | |||
); | |||
-- CREATE INDEX `FK1.ORG_EMPLOYEE.IDX` ON ORG_EMPLOYEE (postalcode ASC); | |||
-- CREATE INDEX `FK2.ORG_EMPLOYEE.IDX` ON ORG_EMPLOYEE (organizer_org_id ASC); | |||
-- CREATE UNIQUE INDEX `ORG_EMPLOYEE.id.IDX_UNIQUE` ON ORG_EMPLOYEE (id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table CLUBROOM | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS CLUBROOM ( | |||
id CHAR(4) NOT NULL UNIQUE, | |||
name NVARCHAR(50) NOT NULL, | |||
postalcode VARCHAR(10) NULL, | |||
street NVARCHAR(80) NULL, | |||
housenumber NVARCHAR(7) NULL, | |||
PRIMARY KEY (id), | |||
-- CONSTRAINT `FK1.CLUBROOM` | |||
FOREIGN KEY (postalcode) | |||
REFERENCES CITY (postalcode) | |||
); | |||
-- CREATE INDEX `FK1.CLUBROOM.IDX` ON CLUBROOM (postalcode ASC); | |||
-- CREATE UNIQUE INDEX `CLUBROOM.id.IDX_UNIQUE` ON CLUBROOM (id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table GAME_EVENT | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS GAME_EVENT ( | |||
id CHAR(4) NOT NULL UNIQUE, | |||
clubroom_id CHAR(4) NULL, | |||
name NVARCHAR(50) NOT NULL, | |||
starttime DATETIME NULL, | |||
endtime DATETIME NULL, | |||
event_fee INT NULL, | |||
extrainfo NVARCHAR(500) NULL, | |||
PRIMARY KEY (id), | |||
-- CONSTRAINT `FK1.GAME_EVENT` | |||
FOREIGN KEY (clubroom_id) | |||
REFERENCES CLUBROOM (id) | |||
); | |||
-- CREATE INDEX `FK1.EVENT.IDX` ON GAME_EVENT (clubroom_id ASC); | |||
-- CREATE UNIQUE INDEX `EVENT.id.IDX_UNIQUE` ON GAME_EVENT (id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new joining table RESERVATION | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS RESERVATION ( | |||
organizer_org_id CHAR(4) NOT NULL, | |||
clubroom_id CHAR(4) NOT NULL, | |||
time DATETIME NULL, | |||
PRIMARY KEY (organizer_org_id, clubroom_id), | |||
-- CONSTRAINT `FK2.RESERVATION` | |||
FOREIGN KEY (clubroom_id) | |||
REFERENCES CLUBROOM (id), | |||
-- CONSTRAINT `FK1.RESERVATION` | |||
FOREIGN KEY (organizer_org_id) | |||
REFERENCES ORGANIZER_ORG (id) | |||
); | |||
-- CREATE INDEX `FK1.RESERVATION.IDX` ON RESERVATION (clubroom_id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new joining table ARRANGEMENT | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS ARRANGEMENT ( | |||
organizer_org_id CHAR(4) NOT NULL, | |||
event_id CHAR(4) NOT NULL, | |||
PRIMARY KEY (organizer_org_id, event_id), | |||
-- CONSTRAINT `FK1.ARRANGEMENT` | |||
FOREIGN KEY (organizer_org_id) | |||
REFERENCES ORGANIZER_ORG (id), | |||
-- CONSTRAINT `FK2.ARRANGEMENT` | |||
FOREIGN KEY (event_id) | |||
REFERENCES GAME_EVENT (id) | |||
); | |||
-- CREATE INDEX `FK2.ARRANGEMENT.IDX` ON ARRANGEMENT (event_id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table TEAM_STATUS | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS TEAM_STATUS ( | |||
team_id CHAR(4) NOT NULL, | |||
event_id CHAR(4) NOT NULL, | |||
team_status VARCHAR(20) NOT NULL, | |||
rank INT NULL, | |||
PRIMARY KEY (team_id, event_id), | |||
-- CONSTRAINT `FK2.TEAM_STATUS` | |||
FOREIGN KEY (event_id) | |||
REFERENCES GAME_EVENT (id), | |||
-- CONSTRAINT `FK1.TEAM_STATUS` | |||
FOREIGN KEY (team_id) | |||
REFERENCES TEAM (id), | |||
-- MariaDB 10.2 implements CHECK constraints | |||
-- https://mariadb.com/kb/en/library/changes-improvements-in-mariadb-102/ | |||
-- Determine your version with query: SELECT @@version | |||
CHECK (rank BETWEEN 1 AND 999), | |||
CHECK ( | |||
team_status = 'playing' OR | |||
team_status = 'registered' OR | |||
team_status = 'played' OR | |||
team_status = 'ranked' | |||
) | |||
); | |||
-- CREATE INDEX `FK1.TEAM_STATUS.IDX` ON TEAM_STATUS (event_id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new (joining) table PLAYER_RANK | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS PLAYER_RANK ( | |||
player_id CHAR(4) NOT NULL UNIQUE, | |||
team_id CHAR(4) NOT NULL, | |||
rank INT NOT NULL, | |||
PRIMARY KEY (player_id, team_id), | |||
-- CONSTRAINT `FK1.PLAYER_RANK` | |||
FOREIGN KEY (player_id) | |||
REFERENCES PLAYER (id), | |||
-- CONSTRAINT `FK2.PLAYER_RANK` | |||
FOREIGN KEY (team_id) | |||
REFERENCES TEAM (id), | |||
-- MariaDB 10.2 implements CHECK constraints | |||
-- https://mariadb.com/kb/en/library/changes-improvements-in-mariadb-102/ | |||
-- Determine your version with query: SELECT @@version | |||
CHECK (rank BETWEEN 1 AND 99) | |||
); | |||
-- CREATE INDEX `FK1.PLAYER_RANK.IDX` ON PLAYER_RANK (player_id ASC); | |||
-- CREATE INDEX `FK2.PLAYER_RANK.IDX` ON PLAYER_RANK (team_id ASC); | |||
-- CREATE UNIQUE INDEX `PLAYER_RANK.player_id.IDX_UNIQUE` ON PLAYER_RANK (player_id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table TEAM_RANK_GLOBAL | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS TEAM_RANK_GLOBAL ( | |||
rank INT NOT NULL UNIQUE, | |||
team_id CHAR(4) NOT NULL UNIQUE, | |||
PRIMARY KEY (rank, team_id), | |||
-- CONSTRAINT `FK1.TEAM_RANK` | |||
FOREIGN KEY (team_id) | |||
REFERENCES TEAM (id), | |||
-- MariaDB 10.2 implements CHECK constraints | |||
-- https://mariadb.com/kb/en/library/changes-improvements-in-mariadb-102/ | |||
-- Determine your version with query: SELECT @@version | |||
CHECK (rank BETWEEN 1 AND 9999) | |||
); | |||
-- CREATE INDEX `FK1.TEAM_RANK.IDX` ON TEAM_RANK_GLOBAL (team_id ASC); | |||
-- CREATE UNIQUE INDEX `TEAM_RANK.rank_UNIQUE` ON TEAM_RANK_GLOBAL (rank ASC); | |||
-- CREATE UNIQUE INDEX `TEAM_RANK.team_id.IDX_UNIQUE` ON TEAM_RANK_GLOBAL (team_id ASC); | |||
-- ----------------------------------------------------- | |||
-- Create new table BETTOR | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS BETTOR ( | |||
id NVARCHAR(20) NOT NULL, | |||
firstname NVARCHAR(30) NOT NULL, | |||
lastname NVARCHAR(30) NOT NULL, | |||
email NVARCHAR(200) NOT NULL, | |||
phone VARCHAR(25) NULL, | |||
IBAN VARCHAR(30) NULL, | |||
SWIFT_bank VARCHAR(15) NULL, | |||
SWIFT_number VARCHAR(20) NULL, | |||
password CHAR(128) NOT NULL, | |||
PRIMARY KEY (id) | |||
); | |||
-- ----------------------------------------------------- | |||
-- Create new table BETTING | |||
-- ----------------------------------------------------- | |||
CREATE TABLE IF NOT EXISTS BETTING ( | |||
bettor_id NVARCHAR(20) NOT NULL, | |||
event_id CHAR(4) NOT NULL, | |||
team_id CHAR(4) NOT NULL, | |||
team_rank_guess INT NOT NULL, | |||
multiplier DECIMAL(4,2) NOT NULL, | |||
initmoney DECIMAL(5,2) NOT NULL, | |||
betstatus NVARCHAR(20) NOT NULL, | |||
PRIMARY KEY (bettor_id, event_id, team_id), | |||
-- CONSTRAINT `FK1.BETTING` | |||
FOREIGN KEY (bettor_id) | |||
REFERENCES BETTOR (id), | |||
-- CONSTRAINT `FK3.BETTING` | |||
FOREIGN KEY (team_id) | |||
REFERENCES TEAM (id), | |||
-- CONSTRAINT `FK2.BETTING` | |||
FOREIGN KEY (event_id) | |||
REFERENCES GAME_EVENT (id), | |||
-- MariaDB 10.2 implements CHECK constraints | |||
-- https://mariadb.com/kb/en/library/changes-improvements-in-mariadb-102/ | |||
-- Determine your version with query: SELECT @@version | |||
CHECK (team_rank_guess BETWEEN 1 AND 99), | |||
CHECK (multiplier BETWEEN 1 AND 10), | |||
CHECK (initmoney BETWEEN 1 AND 999), | |||
CHECK ( | |||
betstatus = 'queued for approval' OR | |||
betstatus = 'accepted' OR | |||
betstatus = 'rejected' OR | |||
betstatus = 'cancelled' OR | |||
betstatus = 'no win' OR | |||
betstatus = 'won' OR | |||
betstatus = 'other' | |||
) | |||
); | |||
-- CREATE INDEX `FK3.BETTING.IDX` ON BETTING (team_id ASC); | |||
-- CREATE INDEX `FK2.BETTING.IDX` ON BETTING (event_id ASC); |
@ -0,0 +1,497 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
NOTE: included data values are mostly fictional and computer-generated, and thus do not contain any real personal data | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table COUNTRY | |||
-- ----------------------------------------------------- | |||
INSERT INTO COUNTRY (id, name) VALUES | |||
('FI', 'Finland'), | |||
('NO', 'Norway'), | |||
('US', 'United States'), | |||
('DE', 'Germany'), | |||
('RU', 'Russia'), | |||
('EE', 'Estonia'), | |||
('JP', 'Japan'), | |||
('AR', 'Argentina'), | |||
('IS', 'Iceland'), | |||
('AT', 'Austria'), | |||
('BR', 'Brazil'), | |||
('DK', 'Denmark'), | |||
('SE', 'Sweden'), | |||
('IR', 'Iran'), | |||
('MT', 'Malta'), | |||
('PR', 'Puerto Rico'), | |||
('SI', 'Slovenia'), | |||
('VN', 'Vietnam') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table CITY | |||
-- ----------------------------------------------------- | |||
INSERT INTO CITY (postalcode, country_id, name) VALUES | |||
('20540', 'FI', 'Halinen'), | |||
('00750', 'FI', 'Helsinki'), | |||
('00880', 'FI', 'Helsinki'), | |||
('00510', 'FI', 'Helsinki'), | |||
('20780', 'FI', 'Kaarina'), | |||
('90404', 'US', 'Santa Monica'), | |||
('80339', 'DE', 'München'), | |||
('397561', 'RU', 'Ни́жний Но́вгород'), | |||
('530-0013', 'JP', '茶屋町駅'), | |||
('5409', 'AR', 'San Roque'), | |||
('7562', 'AT', 'Eltendorf'), | |||
('28750-000', 'BR', 'Trajano De Morais'), | |||
('7830', 'DK', 'Vinderup'), | |||
('147 41', 'SE', 'Tumba'), | |||
('14735', 'US', 'Fillmore'), | |||
('60185', 'US', 'West Chicago'), | |||
('3747', 'US', 'Santiago Del Estero'), | |||
('972 31', 'SE', 'Luleå'), | |||
('90045', 'US', 'Los Angeles'), | |||
('112 20', 'SE', 'Stockholm'), | |||
('1060', 'AT', 'Vienna'), | |||
('50679', 'DE', 'Cologne'), | |||
('06100', 'FI', 'Porvoo'), | |||
('92054', 'US', 'San Diego County'), | |||
('92374', 'US', 'San Bernardino County'), | |||
('5020', 'AT', 'Salzburg'), | |||
('454085', 'RU', 'Челя́бинск'), | |||
('456780', 'RU', 'Челя́бинск'), | |||
('454017', 'RU', 'Челя́бинск'), | |||
('6400', 'DK', 'Sønderborg'), | |||
('371-0022', 'JP', '前橋市'), | |||
('15257', 'SE', 'Fornhöjden'), | |||
('431-1209', 'JP', '浜松市'), | |||
('431-1208', 'JP', '浜松市'), | |||
('432-8058', 'JP', '浜松市'), | |||
('5710', 'AT', 'Salzburg'), | |||
('30285-110', 'BR', 'Vila Alto Vera Cruz'), | |||
('8270', 'DK', 'Højbjerg'), | |||
('433100', 'RU', 'улица Маяковского'), | |||
('55118', 'US', 'West Saint Paul'), | |||
('40212', 'US', 'Louisville'), | |||
('47147', 'IR', 'بخش مرکزی'), | |||
('983-0013', 'JP', '宮城野区'), | |||
('142702', 'RU', 'микрорайон'), | |||
('056', 'VN', 'Hoàng Hoa Thám'), | |||
('413 22', 'SE', 'Guldheden'), | |||
('90768', 'DE', 'Eschenau'), | |||
('09185-220', 'BR', 'Vila Alzira'), | |||
('90009', 'FI', 'Oulu'), | |||
('74130', 'FI', 'Iisalmi'), | |||
('474-1161', 'JP', '松戸市'), | |||
('167-1197', 'JP', '盛岡市'), | |||
('203-1112', 'JP', '山田町'), | |||
('85034', 'US', 'Phoenix'), | |||
('115563', 'RU', 'райо́н Оре́хово-Бори́сово Ю́жное'), | |||
('109429', 'RU', 'улица Капотня'), | |||
('140050', 'RU', 'Мала́ховка'), | |||
('412 62', 'SE', 'Göteborg'), | |||
('951 74', 'SE', 'Luleå'), | |||
('12157', 'DE', 'Berlin'), | |||
('13472-370', 'BR', 'Americana'), | |||
('06725-005', 'BR', 'Cotia'), | |||
('02184', 'US', 'Norfolk County'), | |||
('8300LSB', 'AR', 'Neuquén') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table TEAM | |||
-- ----------------------------------------------------- | |||
INSERT INTO TEAM (id, name, email, phone, postalcode, street, housenumber, IBAN, SWIFT_bank, SWIFT_number) VALUES | |||
('J001', 'Rollihaukat', 'rollihaukat@gmail.com', '+358554319543', '20540', 'Paavinkatu', '4C', 'FI4870716142809720', NULL, NULL), | |||
('J002', 'バトルスピリッツ', 'battlespirits@anet.ne.jp', '+81387453711', '983-0013', '県道仙台塩釜線', NULL, NULL, 'AXIPJPJTCRI', '9188091866'), | |||
('J003', 'FreeRiders', 'freeriders@yahoo.com', '270-209-4072', '40212', 'North Shawnee Terrace', '122', NULL, 'BBFXUS6SXXX', '08126017296'), | |||
('J004', 'Red Hats', 'redhats@mail.ru', '+7(8442)310713', '142702', 'Советская улица', '50E 4', NULL, 'ALTKRUMMXXX', '0386518487'), | |||
('J005', 'Dất Xanh', 'datxahn@gmail.com', '+94(844)37715142', '056', 'Chợ Đầm', NULL, NULL, 'BFTVVNVX038', '990370669360'), | |||
('J006', 'Vita Frost Bringararna', 'vitafrost@altavista.se', '+4603042602798', '413 22', 'Doktor Saléns gata', '26B 2', 'SE0743592495897587599293', NULL, NULL), | |||
('J007', 'Top Rollenspieler', 'toprollenspieler@outlook.com', '+4909471836895', '90768', 'Kannenbergstraße', '46', 'DE62254595460069188490', NULL, NULL), | |||
('J008', 'Comedores de Caveira', 'comcaveira@hotmail.com', '+55(51)30337837', '09185-220', 'Rua Otávio Marques', '4', 'BR6471353461367518996277792HU', NULL, NULL), | |||
('J009', 'برادران نبرد پارسی', 'battlebrothers@protonmail.com', '(+9821)8058594', '47147', 'معلم, کمال محله', NULL, 'IR106484270506068042332457', NULL, NULL) | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table PLAYER | |||
-- ----------------------------------------------------- | |||
INSERT INTO PLAYER (id, team_id, firstname, lastname, email, phone, postalcode, street, housenumber) VALUES | |||
('P001', 'J001', 'Anita', 'Tilhonen', 'anita.tilhonen@gmail.com', '+3584634151416', '20780', 'Hoviherrankatu', '2A 5'), | |||
('P002', 'J001', 'Johanna', 'Nikulainen', 'jniku@gmail.com', '+3580418003929', '90009', 'Jalonkatu', '38'), | |||
('P003', 'J002', 'Sei', 'Kuwana', 'ameonna.sei@excite.co.jp', '+81392789972', '474-1161', 'マツドシ', NULL), | |||
('P004', 'J002', 'Minan', 'Ikegami', 'amaterasu87@lolipop.jp', NULL, '167-1197', 'モリオカシ', NULL), | |||
('P005', 'J002', 'Yuichi', 'Mitsuishi', 'hitodama.yuc@conoha.jp', '+81143557146', '203-1112', 'シモヘイグンヤマダマチ', NULL), | |||
('P006', 'J003', 'Mark', 'Baylor', 'hydra884@gmail.com', '480-207-6961', '85034', 'Dye Street', '2122'), | |||
('P007', 'J003', 'Lisa', 'Ford', 'cartoonqueen@gmail.com', '480-254-7889', '85034', 'East Avenue', '1719'), | |||
('P008', 'J004', 'Esther', 'Bazarova', 'tordlin@imail.ru', '+7(3452)778193', '115563', 'Детский сад №', '36 к6'), | |||
('P009', 'J004', 'Lolita', 'Pirogova', 'bremalin@gmail.com', '+7(8142)274283', '109429', 'Детская музыкальная школа имени Н.Н. Калинина', '3'), | |||
('P010', 'J004', 'Myron', 'Ponomarev', 'stormknight@au.ru', '+7(3452)178318', '140050', 'Люберецкий Дом ребёнка', NULL), | |||
('P011', 'J004', 'Nicanor', 'Tokaryev', 'zialana@sendmail.ru', '+7(8112)133139', '140050', 'улица Суворова', NULL), | |||
('P012', 'J005', 'Lạc', 'Trọng Phu', 'phenomicalevent@gmail.com', NULL, NULL, NULL, NULL), | |||
('P013', 'J006', 'Niki', 'Lindqvist', 'flyswatter@telia.se', '+4601747700680', '412 62', 'Eriksbo Västergärde', '38'), | |||
('P014', 'J007', 'Melanie', 'Schweitzer', 'hardlewain@gmx.com', '+4905872860059', NULL, NULL, NULL), | |||
('P015', 'J007', 'Johanna', 'Wechsler', 'scholtz@web.de', '+4909231339578', '12157', 'Genslerstraße', '7A 8'), | |||
('P016', 'J008', 'Larissa', 'Alves Ferreira', 'larissa.ferreira@gmail.com', '+55(61)32004141', '06725-005', 'Rua Alexandrina', '1126'), | |||
('P017', 'J009', 'علوی', 'فرود', 'bloodlust@gmail.com', NULL, NULL, NULL, NULL), | |||
('P018', 'J009', 'جوادی', 'کسرا', 'swordofheat@yahoo.com', NULL, NULL, NULL, NULL), | |||
('P019', 'J006', 'Sebastian', 'Engström', 'sebastian.engstrom@outlook.com', '+4605207348333', '951 74', 'Knektvägen', '89'), | |||
('P020', 'J005', 'Hàn', 'Hữu Nghi', 'uberiorr@gmail.com', NULL, NULL, NULL, NULL), | |||
('P021', 'J005', 'Lê', 'Đình Hưng', 'soldier_of_win@gmail.com', NULL, NULL, NULL, NULL), | |||
('P022', 'J008', 'Beatrice', 'Cavalcanti Pinto', 'boitatacrawler@gmail.com', '+55(11)49453672', '13472-370', 'Rua São Bento', '1570'), | |||
('P023', 'J001', 'Senja', 'Virolainen', 'moaderspin@outlook.com', '+3580507399907', '74130', 'Pihlajaharjuntie', '2') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table ORGANIZER_ORG | |||
-- ----------------------------------------------------- | |||
INSERT INTO ORGANIZER_ORG (id, name, email, phone, postalcode, street, housenumber) VALUES | |||
('O001', 'Peliturnarit', 'firstname.lastname@peliturnarit.fi', '+3585043239534', '00750', 'Keskitie', '20'), | |||
('O002', 'Global Board Game Association', 'firstname.lastname@globalbgass.com', '310-315-5982', '90404', '18th Court', '4'), | |||
('O003', 'Erste Dungeonreihenfolge', 'vorname.nachname@erdunfolge.de', '+4907356748808', '80339', 'Hartwaldstraße', '5'), | |||
('O004', 'северные медведи', 'imya.familiya@sevnesti.ru', '+7(8552)465742', '397561', 'городское поселение Пристень', '21'), | |||
('O005', 'ロイヤルゲーマー', 'namae.myoji@roiyarugema.ja', '+81398962866', '530-0013', 'Kurashiki', '中庄'), | |||
('O006', 'Organización de mejora de nivel', 'nombre.apellido@orgnivel.ar', '+541146604728', '5409', 'Calle Ínter de Milán', '2A'), | |||
('O007', 'Europäische Grenze Spielen', 'vorname.nachname@eurspielen.at', '+4306762298756', '7562', 'Zipfgasse', '2'), | |||
('O008', 'Associação Sul-Americana de Jogos de Tabuleiro', 'primeiro.ultimo@tabuleiro.br', '+55(28)90807333', '28750-000', 'Rua Armindo Sena', '1'), | |||
('O009', 'Ægte spillere', 'fornavn.efternavn@agtespillere.dk', '+4581563317', '7830', 'Toften', '11'), | |||
('O010', 'Förlorade Vikingarna', 'fornamn.efternamn@forloradeviking.se', '+4609112343501', '147 41', 'Grödingevägen', '7C'), | |||
('O011', 'North American Challenger Teams', 'firstname.lastname@americanchallenger.com', '218-212-8737', '14735', 'Lowel Road', '1') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table ORG_EMPLOYEE | |||
-- ----------------------------------------------------- | |||
INSERT INTO ORG_EMPLOYEE (id, organizer_org_id, firstname, lastname, email, phone, postalcode, street, housenumber) VALUES | |||
('T001', 'O001', 'Heikki', 'Isomaa', 'heikki.isomaa@peliturnarit.fi', '+3584634176571', '00880', 'Tulppatie', '7E 4'), | |||
('T002', 'O001', 'Niina', 'Pousi', 'niina.pousi@peliturnarit.fi', '+3580403372373', '06100', 'Rantakatu', '5A 6'), | |||
('T003', 'O002', 'Paul', 'Hinkel', 'paul.hinkel@globalbgass.com', '209-226-5969', '02184', 'Laurel Road', '4'), | |||
('T004', 'O002', 'Susan', 'Burns', 'susan.burns@globalbgass.com', '209-235-4982', '92374', 'Post Street', '3A 5'), | |||
('T005', 'O003', 'Elia', 'Schwerner', 'elia.schwerner@erdunfolge.de', '+4909087794512', '5020', 'Raschenbergstraße', '11'), | |||
('T006', 'O004', 'Roza', 'Dmitrievna', 'roza.dmitrievna@sevnesti.ru', '+7(3435)820509', '454085', 'улица Грибоедова', '30'), | |||
('T007', 'O004', 'Berezina', 'Yanovna', 'berezina.yanovna@sevnesti.ru', '+7(3513)796752', '456780', 'Советская улица', '40A 12'), | |||
('T008', 'O004', 'Viktor', 'Vsevolotov', 'viktor.vsevolotov@sevnesti.ru', '+7(8552)712462', '454017', 'улица Румянцева', '31B 34'), | |||
('T009', 'O009', 'Peter', 'Mikkelsen', 'peter.mikkelsen@agtespillere.dk', '+4541449509', '6400', 'Grundtvigsparken', '4C 1'), | |||
('T010', 'O005', 'Fumihito', 'Kawagoe', 'fumihito.kawagoe@roiyarugema.ja', '+81749619914', '371-0022', '津久田停車場前橋線', '46'), | |||
('T011', 'O010', 'Nikita', 'Söderberg', 'nikita.soderberg@forloradeviking.se', '+4609134963893', '15257', 'Fuxvägen 3', '3'), | |||
('T012', 'O005', 'Toshikage', 'Ishigami', 'toshikage.ishigami@roiyarugema.ja', '+81846322201', '431-1209', 'イハラ美容室, 門前通り', NULL), | |||
('T013', 'O006', 'Adrían', 'Guzmán', 'adrian.guzman@orgnivel.ar', '+541142048156', '8300LSB', 'Socompa', '355'), | |||
('T014', 'O007', 'Lucas', 'Semmelweis', 'lucas.semmelweis@eurspielen.at', '+4306995884294', '5710', 'Dorfstraße', '5D 16'), | |||
('T015', 'O008', 'Catarina', 'de Freitas', 'catarina.freitas@tabuleiro.br', '+55(62)73309001', '30285-110', 'Rua Desembargador Saraiva', '17'), | |||
('T016', 'O009', 'Amanda', 'Danielsen', 'amanda.danielsen@agtespillere.dk', '+4553629301', '8270', 'Filippavej', '39'), | |||
('T017', 'O004', 'Isabella', 'Samoylova', 'isabella.samoylova@sevnesti.ru', '+7(8552)882836', '433100', 'улица Маяковского', '14'), | |||
('T018', 'O005', 'Yasumoto', 'Maihara', 'yasumoto.maihara@roiyarugema.ja', '+81628190292', '432-8058', '浜松市立可新図書館, 舞阪竜洋線', NULL), | |||
('T019', 'O011', 'Paul', 'Allison', 'paul.allison@americanchallenger.com', '218-227-0680', '55118', 'Edith Drive', '293') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table CLUBROOM | |||
-- ----------------------------------------------------- | |||
INSERT INTO CLUBROOM (id, name, postalcode, street, housenumber) VALUES | |||
('LAUT', 'Lautakomero', '00510', 'Kajaaninkatu', '1'), | |||
('HILL', 'Hillcavern Domain', '1060', 'Obere Windmühle', '5'), | |||
('DRAG', 'Dragon\'s Lair', '112 20', 'Kungsholmstorg', '8'), | |||
('STRA', 'Strategicon', '90045', 'Century Bulevard', '5711 W'), | |||
('CONG', 'Congress-Centrum Nord Koelnmesse', '50679', 'Messeplatz', '1') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table GAME_EVENT | |||
-- ----------------------------------------------------- | |||
INSERT INTO GAME_EVENT (id, clubroom_id, name, starttime, endtime, event_fee, extrainfo) VALUES | |||
( | |||
'E001', | |||
'LAUT', | |||
'DnD Rogue Challenge', | |||
'2019-11-23 14:00:00.000', | |||
'2019-11-24 06:00:00.000', | |||
10, | |||
'Come to see world\'s top teams challenging each other.' | |||
), | |||
( | |||
'E002', | |||
'STRA', | |||
'Strategicon', | |||
'2020-02-14 09:00:00.000', | |||
'2020-02-17 22:00:00.000', | |||
200, | |||
'The tournament is one of the biggest and takes place in California, United States.' | |||
), | |||
( | |||
'E003', | |||
NULL, | |||
'DnDSports', | |||
'2020-01-06 08:30:00.000', | |||
'2020-01-12 18:00:00.000', | |||
5, | |||
'Challenge top teams in this online gaming event and win your place!' | |||
), | |||
( | |||
'E004', | |||
'CONG', | |||
'Gamescom', | |||
'2020-08-25 08:00:00.000', | |||
'2020-08-29 23:59:59.000', | |||
70, | |||
'Diverse german game tournament brings players together around the world!' | |||
) | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table RESERVATION | |||
-- ----------------------------------------------------- | |||
INSERT INTO RESERVATION (organizer_org_id, clubroom_id, time) VALUES | |||
('O001', 'LAUT', '2019-11-16 12:44:23.000'), | |||
('O007', 'CONG', NULL), | |||
('O011', 'STRA', '2019-08-02 13:42:15.534') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table ARRANGEMENT | |||
-- ----------------------------------------------------- | |||
INSERT INTO ARRANGEMENT (organizer_org_id, event_id) VALUES | |||
('O001', 'E001'), | |||
('O002', 'E002'), | |||
('O007', 'E004'), | |||
('O011', 'E003'), | |||
('O008', 'E002') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Data for table TEAM_STATUS | |||
-- ----------------------------------------------------- | |||
INSERT INTO TEAM_STATUS (team_id, event_id, team_status, rank) VALUES | |||
('J001', 'E001', 'ranked', 3), | |||
('J008', 'E001', 'played', NULL), | |||
('J005', 'E004', 'registered', NULL), | |||
('J006', 'E001', 'ranked', 1), | |||
('J002', 'E002', 'registered', NULL), | |||
('J003', 'E003', 'registered', NULL), | |||
('J007', 'E004', 'registered', NULL) | |||
; | |||
-- ----------------------------------------------------- | |||
-- Data for table PLAYER_RANK | |||
-- ----------------------------------------------------- | |||
INSERT INTO PLAYER_RANK (player_id, team_id, rank) VALUES | |||
('P001', 'J001', 2), | |||
('P023', 'J001', 1), | |||
('P006', 'J003', 2), | |||
('P007', 'J003', 1), | |||
('P005', 'J002', 2), | |||
('P022', 'J008', 2), | |||
('P010', 'J004', 4), | |||
('P018', 'J009', 2), | |||
('P002', 'J001', 3), | |||
('P003', 'J002', 1), | |||
('P014', 'J007', 2), | |||
('P020', 'J005', 2), | |||
('P009', 'J004', 1), | |||
('P008', 'J004', 2), | |||
('P013', 'J006', 2), | |||
('P012', 'J005', 1), | |||
('P011', 'J004', 3), | |||
('P015', 'J007', 1), | |||
('P004', 'J002', 3), | |||
('P019', 'J006', 1), | |||
('P016', 'J008', 1), | |||
('P017', 'J009', 1), | |||
('P021', 'J005', 3) | |||
; | |||
-- ----------------------------------------------------- | |||
-- Data for table TEAM_RANK_GLOBAL | |||
-- ----------------------------------------------------- | |||
INSERT INTO TEAM_RANK_GLOBAL (rank, team_id) VALUES | |||
(432, 'J001'), | |||
(257, 'J003'), | |||
(45, 'J005'), | |||
(786, 'J009'), | |||
(324, 'J006'), | |||
(127, 'J004'), | |||
(74, 'J002'), | |||
(675, 'J007'), | |||
(390, 'J008') | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table BETTOR | |||
-- ----------------------------------------------------- | |||
INSERT INTO BETTOR (id, firstname, lastname, email, phone, IBAN, SWIFT_bank, SWIFT_number, password) VALUES | |||
( | |||
'ForceWeaver', | |||
'Niko', | |||
'Tepponen', | |||
'forceweaver77@hotmail.com', | |||
'0445321770', | |||
'FI7176990982569721', | |||
NULL, | |||
NULL, | |||
'd9bb16f24a9d35a57b6dec1603e9d12780dce7116d160a743b6fee5cdcb4ed70c494b6b838b7b5bff286079f19f6295d27fef573883eae6e9ec1d604d79b4ec7' | |||
), | |||
( | |||
'Katotoku', | |||
'Lian', | |||
'Yü', | |||
'katotokuyu@baidu.com', | |||
'13073390338', | |||
NULL, | |||
'GDBKCN22GZ1', | |||
'634863382282', | |||
'0caa4969caf0a65a89de430a1af8db3ce654c46415b63af5d7e959524e972d2de83b6a405cd60d9940c6a6d4cd760328e580e63a05b71d9312d3a6b2f2b297bf' | |||
), | |||
( | |||
'Tadotaka', | |||
'Gang', | |||
'Ch\'ien', | |||
'tadotakagang@baidu.com', | |||
'+8613013867507', | |||
NULL, | |||
'CRESCNSH', | |||
'056656945387', | |||
'f8af7b436482adf71a00de95be18c944775b0cb9734332ccd5f323b3d6e6f92da67941c9469a478f4af17b6344078dfdfc2992f7a62b0b0ba93762cdf83d4ffc' | |||
), | |||
( | |||
'Katoteshi', | |||
'Cong', 'Hsiao', | |||
'katoteshicong@yahoo.com', | |||
'+13063889088', | |||
NULL, 'PCBCCNBJAHX', | |||
'687790432934', | |||
'e4507172adcf0608b307ab4d27341754cbcd54d03c06ad8848903ef88a5a5fc60df11fa5e6ab4b8d9b0e25b7fd16a3cce9e4e432137b653d432169f0ed16acde' | |||
), | |||
( | |||
'Sandgrinder', | |||
'Evgenija', | |||
'Balentin', | |||
'sandgrinder343@gmail.com', | |||
'+48882484598', | |||
NULL, | |||
'EBOSPLPW005', | |||
'6267746983', | |||
'8c62deedfe2a5ce2136b4afe9925e04453f44e3ead02b8ac931831542df95e2cc2d7da45584c59a6eee179c87ac66a37a1669c17688ba2d00dea437f932b8b21' | |||
), | |||
( | |||
'Lothran', | |||
'Heiða', | |||
'Þorgrímsdóttir', | |||
'lothranwiz@outlook.com', | |||
'+35465553958', | |||
NULL, | |||
'SISLISRE', | |||
'04911539522202', | |||
'11325a7fdd174376157a55557efa16eb9a6a50a95fa0f32134c3be1722dbfcbb0555d2b31215eaac3b2dbabed9897ee6b320b7ca53d52450cdbc363eea64f267' | |||
), | |||
( | |||
'Isengrin', | |||
'Lóa', | |||
'Hervinsson', | |||
'isegrin82@hotmail.com', | |||
'+35465558357', | |||
NULL, | |||
'DABADKKKBAL', | |||
'4681967034', | |||
'2486f5f8ac1bf7e2d85942f57748d9a8c1cdfcb090f0c42ec096daa0df4b961029e2bb72a419014eaf506ac0176de728e864fc5be4c98c221b9c3ba78f68c6c1' | |||
), | |||
( | |||
'waterheaver', | |||
'Ila', | |||
'Fouquet', | |||
'waterheaver12@hotmail.com', | |||
NULL, | |||
NULL, | |||
'ALLZFRPP', | |||
'7369781413', | |||
'9c2a933c3543682a6497fa3ed4fdb128b1582b57644cd56a64d46769c38149ed6ddcfe8ce2b72fa0c4463901f80d127a3fe1498bfc72d30f674654a15509a83f' | |||
), | |||
( | |||
'Bugaloo', | |||
'Casper', | |||
'Berge', | |||
'bugaloozoo@gmail.com', | |||
NULL, | |||
NULL, | |||
'BOFAIE3XSBL', | |||
'7746897535', | |||
'dd61748a588b01a76fddea3af6d50e9a92d4d4dcb157eaa12063c14962af38c2061cdc30cfaac973ea2593b063f3a29b9fe4030d52f8e7a1d82ccc86df93dae8' | |||
), | |||
( | |||
'Undertaker', | |||
'Felicia', | |||
'Thoresen', | |||
'undertakergin6@yahoo.com', | |||
NULL, | |||
NULL, | |||
'DABANO22', | |||
'4310141078', | |||
'468ff41e74846c00473f90893b499cf63831d967b63daa4c78aaa23dcacc9ad75309608d2540685af9299ed3a8116521454fb27d6b80d5a41feae1380c24e3aa' | |||
), | |||
( | |||
'Jackhammer', | |||
'Felix', | |||
'Grunewald', | |||
'jackthehammer@outlook.com', | |||
'+4906432579977', | |||
NULL, | |||
'VPCSSESSCLP', | |||
'29352045380419', | |||
'abf8800c00f692150ae944dbc4e7d328b77cd5a42fb307a02045d09944285657b5fe77f06a9ef9f0e762affb2e59f85ab597e5c290e4788ce91b3ec73c3600c9' | |||
), | |||
( | |||
'eranen', | |||
'Kristian', | |||
'Eisenberg', | |||
'eranen_berg@hotmail.com', | |||
NULL, | |||
NULL, | |||
'DABASESX', | |||
'0171699755', | |||
'0541bbccef9268dfbb11fccfb26e2a83205233b677dd8516ef020466cd46581de5947fb9b686d03bd4e71b255cc09e90b5832ccc591cf2ccafe8e9b525051d69' | |||
), | |||
( | |||
'Rutida', | |||
'Niklas', | |||
'Friedmann', | |||
'rutidarouting@gmail.com', | |||
NULL, | |||
NULL, | |||
'DKNBDKK3', | |||
'266423564818', | |||
'98751076c8b89f2c667b2a15abe6eb7137b666cd676a79a3cc137d594dc4cdd8e934711a8a66afe78ec7df58aac40d8eb4e2932b15952ff7d77676370e68a74c' | |||
) | |||
; | |||
-- ----------------------------------------------------- | |||
-- Insert data for table BETTING | |||
-- ----------------------------------------------------- | |||
INSERT INTO BETTING (bettor_id, event_id, team_id, team_rank_guess, multiplier, initmoney, betstatus) VALUES | |||
('Isengrin', 'E004', 'J007', 2, 2.4, 112.50, 'queued for approval'), | |||
('Katoteshi', 'E002', 'J002', 1, 1.55, 14.00, 'queued for approval'), | |||
('Rutida', 'E003', 'J003', 3, 4.5, 34.20, 'queued for approval'), | |||
('ForceWeaver', 'E001', 'J001', 1, 7, 90, 'no win'), | |||
('Sandgrinder', 'E001', 'J001', 2, 5.4, 140, 'no win') | |||
; |
@ -0,0 +1,350 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 1 | |||
Database company owning the tournament database has changed its terms of use for the tournament application platform. Major changes for players include requirement of having personal contact information connected to new and existing accounts. To be specific, the required information is: | |||
- phone number | |||
- postal code | |||
- street | |||
- house number | |||
Earlier this information was optional and only email information was required. | |||
A database administrator sends a group email to notify players about the changed terms of use. The administrator wants to send the email only for players lacking the required contact information to avoid spamming messages unnecessarily. The email message has a clearly stated deadline after which the database company reserves rights to delete player information from the tournament database unless the new terms of use conditions have been met. | |||
To avoid errors, lack of information and misunderstandings, the administrator wants to send the message to team common email addresses, as well. This is useful in cases where players can't be reached via their personal email addresses. | |||
Create a SQL query which meets the administrator requirements. | |||
*/ | |||
-- ----------------------------------------------------- | |||
SELECT | |||
P.firstname, | |||
P.lastname, | |||
P.email AS player_email, | |||
T.email AS team_email | |||
FROM PLAYER P | |||
JOIN TEAM T | |||
ON P.team_id = T.id | |||
WHERE P.phone IS NULL OR | |||
P.postalcode IS NULL OR | |||
P.street IS NULL OR | |||
P.housenumber IS NULL | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 2 | |||
Find cities and towns which are not used or are not connected to the following data: | |||
- organization worker | |||
- organization | |||
- players | |||
- teams | |||
- clubrooms | |||
Query results should contain a list of unused cities and towns, including possible country codes. | |||
Required query operations: | |||
1) Get all possible postal codes in the database and combine them into a single column | |||
2) Compare the combined column with the values of postalcode column in CITY table | |||
3) Print those values of postalcode column in CITY table which are not present in | |||
the combined query table generated in step 1) | |||
*/ | |||
-- ----------------------------------------------------- | |||
SELECT CITY.* FROM ( | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM ORG_EMPLOYEE | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM ORGANIZER_ORG | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM PLAYER | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM TEAM | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM CLUBROOM | |||
) USED_ZIPCODES | |||
RIGHT JOIN CITY ON | |||
USED_ZIPCODES.postalcode_used = CITY.postalcode | |||
WHERE USED_ZIPCODES.postalcode_used IS NULL | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 3 | |||
Same description than in task 2. Instead of cities and towns, retrieve information of unused countries (country codes and county names) | |||
*/ | |||
-- ----------------------------------------------------- | |||
SELECT COUNTRY.* FROM COUNTRY | |||
LEFT JOIN CITY ON | |||
COUNTRY.id = CITY.country_id | |||
WHERE CITY.name IS NULL | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 4 | |||
Executives and strategy makers of the database company are interested in possibilities of the new tournament database. Therefore, they want some statistics based on the current data. Tournament database administrators receive a request and are tasked to fetch information regarding to tournament host countries and countries of participating teams. The executives want more information to estimate whether the company should increase number of available arenas and clubrooms for tournament events. The statistics will be used in an internal report which is appointed to the executives and the strategy makers. | |||
The database administrators proceed and fetch the required information from the tournament database. To be specific, they print the following information: | |||
- tournament event name | |||
- tournament event host country | |||
- participated teams and their names | |||
- home country of each team | |||
Printed output should have information whether a team has already played or just registered to an event. Additionally, the output should state whether an event has already been organized or not. | |||
Sort the output primarily by tournament event names in descending order, and secondarily by team country names in descending order. | |||
Output should also include tournament events without physical location (online events). | |||
*/ | |||
-- ----------------------------------------------------- | |||
SELECT | |||
T.name AS event_name, | |||
(CASE WHEN MK.id IS NULL THEN 'online' ELSE MK.id END) AS event_country, | |||
(CASE WHEN CURDATE() > T.endtime THEN 'organized' ELSE 'planned' END) AS event_status, | |||
J.name AS team_name, | |||
MJ.id AS team_country, | |||
JS.team_status | |||
FROM TEAM J | |||
JOIN TEAM_STATUS JS | |||
ON JS.team_id = J.id | |||
JOIN GAME_EVENT T | |||
ON T.id = JS.event_id | |||
LEFT JOIN CLUBROOM K | |||
ON K.id = T.clubroom_id | |||
/* team postal code */ | |||
JOIN CITY PKJ | |||
ON PKJ.postalcode = J.postalcode | |||
JOIN COUNTRY MJ | |||
ON MJ.id = PKJ.country_id | |||
/* clubroom postal code */ | |||
LEFT JOIN CITY PKK | |||
ON PKK.postalcode = K.postalcode | |||
LEFT JOIN COUNTRY MK | |||
ON MK.id = PKK.country_id | |||
ORDER BY event_name ASC, team_country ASC | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
TEHTÄVÄ 5 | |||
Which team has been the most popular guess among bettors? How many times the team has been betted on to? Fetch the information from the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
USE tournament_db; | |||
SELECT | |||
J.name AS team_name, | |||
COUNT(V.team_id) AS team_guesses_total | |||
FROM BETTING V | |||
JOIN TEAM J | |||
ON J.id = V.team_id | |||
GROUP BY J.name, V.team_id | |||
ORDER BY team_guesses_total DESC | |||
LIMIT 1; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 6 | |||
Print average ranking of each team in tournament events where it has been played in. | |||
The print output should include | |||
- team name | |||
- how many times a team has been betted on to | |||
- average rank guess for a team in all tournament events among bettors | |||
- average rank of a team in all tournaments | |||
- number of tournaments a team has been played in | |||
*/ | |||
-- ----------------------------------------------------- | |||
SELECT | |||
J.name AS team_name, | |||
COUNT(V.team_id) AS team_guesses_total, | |||
ROUND(AVG(V.team_rank_guess),2) AS team_rank_guess_AVG, | |||
( | |||
CASE | |||
WHEN | |||
AVG(JS.rank) IS NOT NULL | |||
THEN | |||
ROUND(AVG(JS.rank),2) | |||
ELSE | |||
'never ranked' | |||
END | |||
) AS 'team_avg.rank', | |||
( | |||
CASE | |||
WHEN | |||
JS.team_status = 'played' OR JS.team_status = 'ranked' | |||
THEN | |||
COUNT(JS.team_id) | |||
ELSE | |||
0 | |||
END | |||
) AS team_gamestotal | |||
FROM BETTING V | |||
JOIN TEAM J | |||
ON J.id = V.team_id | |||
JOIN TEAM_STATUS JS | |||
ON JS.team_id = V.team_id | |||
GROUP BY J.name, V.team_id, JS.team_status | |||
ORDER BY team_guesses_total DESC; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 7 | |||
The chief executive officer (CEO) of the database company want to know profits gained by the company and organizers from tournament events. Accountant suggest to get expenses, as well. The CEO agrees. | |||
The accountant delivers the request to database administrators who promise to fetch the information from the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
SELECT | |||
PT.name AS event_name, | |||
SUM(PT.event_fee) AS event_profit, | |||
COUNT(JS.team_id) AS participated_teams_count | |||
FROM TEAM_STATUS JS | |||
JOIN GAME_EVENT PT | |||
ON JS.event_id = PT.id | |||
GROUP BY PT.name; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 8 | |||
The database company board holds a meeting where an employee suggests to obtain better statistics about geographical diversity of tournament teams, players and bettors, not forgetting information about the most active userbase by countries around the world. Most participants agree with the employee. | |||
Another employee delivers the request to tournament database administrators who promise to fetch the information for the company board. | |||
Tournament user groups are as follows: | |||
- tournament event organizer employees | |||
- tournament event organizer | |||
- team players | |||
- team | |||
Obtain a country-specific group statistics for the described user groups. | |||
*/ | |||
-- ----------------------------------------------------- | |||
SELECT | |||
JT.id AS id, | |||
CONCAT('employee') AS 'group', | |||
M1.name AS country_name | |||
FROM ORG_EMPLOYEE JT | |||
JOIN CITY PJT | |||
ON PJT.postalcode = JT.postalcode | |||
JOIN COUNTRY M1 | |||
ON M1.id = PJT.country_id | |||
UNION | |||
SELECT | |||
JO.id AS id, | |||
CONCAT('organizer') AS 'group', | |||
M2.name AS country_name | |||
FROM ORGANIZER_ORG JO | |||
JOIN CITY PJO | |||
ON PJO.postalcode = JO.postalcode | |||
JOIN COUNTRY M2 | |||
ON M2.id = PJO.country_id | |||
UNION | |||
SELECT | |||
PE.id AS id, | |||
CONCAT('player') AS 'group', | |||
M3.name AS country_name | |||
FROM PLAYER PE | |||
JOIN CITY PPE | |||
ON PPE.postalcode = PE.postalcode | |||
JOIN COUNTRY M3 | |||
ON M3.id = PPE.country_id | |||
UNION | |||
SELECT | |||
JK.id AS id, | |||
CONCAT('team') AS 'group', | |||
M4.name AS country_name | |||
FROM TEAM JK | |||
JOIN CITY PJK | |||
ON PJK.postalcode = JK.postalcode | |||
LEFT JOIN COUNTRY M4 | |||
ON M4.id = PJK.country_id | |||
ORDER BY country_name ASC; |
@ -0,0 +1,400 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 9 | |||
Database team has recruited a new inexperienced employee. The new employee is quite unsure about structure of the tournament database, and he/she is missing common knowledge about primary and foreign keys. | |||
Being unaware of his/her inexperience, the database team gives him/her a task to add a new clubroom with the following information: | |||
- id: LAPP | |||
- name: L'Apparemment Café | |||
- postal code, city, maa: 75003, Quartier des Archives, France | |||
- street: Rue des Coutures Saint-Gervais 18 | |||
The operation fails. Why? | |||
Verbal answer: | |||
- Clubroom postal code (reference key value) does not exist | |||
in the primary key CITY.postalcode | |||
- France does not exist/is not determined in the database at all | |||
Therefore, keeping constraints and basic ruleset in mind, the whole operation should be | |||
started by adding missing country data for France (COUNTRY table) after which adding | |||
necessary postal code data is required (CITY table). Afterwards, adding the new | |||
clubroom is possible. | |||
*/ | |||
-- --------------------------- | |||
-- FAILING/INVALID QUERY | |||
-- INSERT INTO CLUBROOM (id, name, postalcode, street, housenumber) VALUES | |||
-- ('LAPP', 'L\'Apparemment Café', '75003', 'Rue des Coutures Saint-Gervais', '18'); | |||
-- --------------------------- | |||
-- SUCCEEDING/VALID QUERY | |||
-- NOTE! Brancing condition: in later exercises, COUNTRY table contains new column 'id_a3' | |||
-- At this moment, the column does not exist. | |||
-- In this answer, both options are considered. | |||
-- ----------------------------------------------------- | |||
/* | |||
Because the user could have executed later presented ALTER queries even now, | |||
we must determine column count of COUNTRY table before inserting any data. | |||
Therefore, a new function and SQL procedure were developed. | |||
FUNCTION: | |||
If 'XX' column exists, return value 1. Otherwise, return NULL. | |||
Because ALTER queries affect column structure of a database, this function | |||
is necessary. At this moment, we don't know whether the target table | |||
contains 'XX' column or not. | |||
PROCEDURE: | |||
Proceed based on function return value. In other words, perform | |||
different operation based on whether the 'XX' column exists or not. | |||
Insert correct amount of data to the target table. | |||
The procedure is quite unscalable but works in this case. | |||
In this case, the referred target table is COUNTRY and the checked column is 'id_a3' | |||
*/ | |||
DROP FUNCTION IF EXISTS columnCheck; | |||
DROP PROCEDURE IF EXISTS INSERT_countryValues; | |||
DELIMITER // | |||
-- ------------- | |||
CREATE FUNCTION columnCheck(db VARCHAR(50), tbl VARCHAR(50), col VARCHAR(50)) | |||
RETURNS INT | |||
DETERMINISTIC | |||
BEGIN | |||
RETURN IF((SELECT COUNT(*) AS COLUMN_RETURN FROM INFORMATION_SCHEMA.COLUMNS WHERE | |||
TABLE_SCHEMA = db AND TABLE_NAME = tbl AND COLUMN_NAME = col), | |||
1, NULL); | |||
END// | |||
-- ------------- | |||
CREATE PROCEDURE INSERT_countryValues( | |||
database_input VARCHAR(50), | |||
table_input VARCHAR(50), | |||
column_input VARCHAR(50), | |||
id_input CHAR(2), | |||
id_a3_input CHAR(3), | |||
dialing_code_input VARCHAR(5), | |||
name_input NVARCHAR(20) | |||
) | |||
BEGIN | |||
IF (SELECT columnCheck(database_input, table_input, column_input)) IS NOT NULL | |||
THEN | |||
INSERT INTO COUNTRY (id, id_a3, dialing_code, name) | |||
VALUES (id_input, id_a3_input, dialing_code_input, name_input) | |||
ON DUPLICATE KEY UPDATE | |||
id_a3 = id_a3_input, | |||
dialing_code = dialing_code_input, | |||
name = name_input | |||
; | |||
ELSE | |||
INSERT INTO COUNTRY (id, name) | |||
VALUES (id_input, name_input) | |||
ON DUPLICATE KEY UPDATE | |||
name = name_input | |||
; | |||
END IF; | |||
END// | |||
DELIMITER ; | |||
-- ----------------------------------------------------- | |||
-- 1) Add missing country information into COUNTRY table in tournament_db | |||
CALL INSERT_countryValues('tournament_db', 'COUNTRY', 'id_a3', 'FR', 'FRA', '33', 'France'); | |||
-- 2) Add city information | |||
INSERT INTO CITY (postalcode, country_id, name) VALUES | |||
('75003', 'FR', 'Quartier des Archives'); | |||
-- 3) Add new clubroom | |||
INSERT INTO CLUBROOM (id, name, postalcode, street, housenumber) VALUES | |||
('LAPP', 'L\'Apparemment Café', '75003', 'Rue des Coutures Saint-Gervais', '18'); | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 10 | |||
Game tournament organizer LFG Australia gets information about new game tournament "2020 NSW Family Tournaments". The organizer wants to join our tournament platform and add information about the new game tournament immediately. The tournament has additional organizer, american Global Board Game Association, which determinates participation fee of 160.09 australian dollars (use equivalent euro value 99). | |||
The tournament event has marketing description which states: "Unforgettable and very unique board game event in the middle of Australian summer, hard to forget! Join today." | |||
The organizer has retrieved the following additional information about the event site: | |||
- Name: The Games Cube | |||
- Contact information: 79 Phillip Street, Parramatta, NSW 2150, Australia | |||
Organizer information is as follows: | |||
- Name: LFG Australia | |||
- Contact information: 12 Morehead Street, Redfern (Sydney), New South Wales, 2016, Australia | |||
- Email: firstname.lastname@@lfg-aus.com.au | |||
- Phone: unknown | |||
Organizer contact person information is as follows: | |||
- Name: Sophia Timms | |||
- Contact information: 11 R.L. Gambling Street, The Berri Barmera Council, 5343, Australia | |||
- Phone: +61(03)53840554 | |||
- Email: sophia.timms@lfg-aus.com.au | |||
Event calendar period is 16th - 17th May 2020. | |||
Using this information, add a new event reservation with relevant data to the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Add new country (Australia) | |||
CALL INSERT_countryValues('tournament_db', 'COUNTRY', 'id_a3', 'AU', 'AUS', '61', 'Australia'); | |||
-- 2) Add postal codes of the organizer, the employee and the tournament site (city) | |||
INSERT INTO CITY (postalcode, country_id, name) VALUES | |||
('2150', 'AU', 'Parramatta'), | |||
('2016', 'AU', 'Redfern'), | |||
('5343', 'AU', 'The Berri Barmera Council') | |||
; | |||
-- 3) Add the new organizer | |||
INSERT INTO ORGANIZER_ORG (id, name, email, phone, postalcode, street, housenumber) VALUES | |||
('O012', 'LFG Australia', 'firstname.lastname@@lfg-aus.com.au', NULL, '2016', 'Morehead Street', '12') | |||
; | |||
-- 4) Add the new employee | |||
INSERT INTO ORG_EMPLOYEE (id, organizer_org_id, firstname, lastname, email, phone, postalcode, street, housenumber) VALUES | |||
('T020', 'O012', 'Sophia', 'Timms', 'sophia.timms@lfg-aus.com.au', '+61(03)53840554', '5343', 'R.L. Gambling Street', '11') | |||
; | |||
-- 5) Add the new tournament event site (clubroom) | |||
INSERT INTO CLUBROOM (id, name, postalcode, street, housenumber) VALUES | |||
('GACU', 'The Games Cube', '2150', 'Phillip Street', '79') | |||
; | |||
-- 6) Add a new reservation | |||
INSERT INTO RESERVATION (organizer_org_id, clubroom_id, time) VALUES | |||
('O012', 'GACU', '2019-12-07 17:39:43.643') | |||
; | |||
-- 7) Add the new tournament event, link it to the new clubroom | |||
INSERT INTO GAME_EVENT (id, clubroom_id, name, starttime, endtime, event_fee, extrainfo) VALUES | |||
('E005', 'GACU', '2020 NSW Family Tournaments', '2020-05-16 00:00:00.000', '2020-05-17 23:59:59.999', 99, 'Unforgettable and very unique board game event in the middle of Australian summer, hard to forget! Join today.') | |||
; | |||
-- 8) Add a new arrangement | |||
INSERT INTO ARRANGEMENT (organizer_org_id, event_id) VALUES | |||
('O012', 'E005'), | |||
('O002', 'E005') | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 11 | |||
The database company receives registration information from a new team, known as Mahokara Team, from New Zealand. The team provides the following information: | |||
- Email: mahorakateam@gmail.com | |||
- Contact information: 16 Majoribanks Street, Wellington, 6011, New Zealand | |||
- SWIFT bank: ANZBNZ22058 | |||
- SWIFT account number: 05835020297713 | |||
- Global ranking: 156 | |||
At the moment, the team has three active players with the following information: | |||
Player 1 | |||
- Name: Alyssa Trickett | |||
- Contact information: 50 Edinburgh Drive, Boydtown (Queenstown), 9348, New Zealand | |||
- Phone: +64(027)5721709 | |||
- Email: mohokai96@outlook.com | |||
Player 2 | |||
- Name: Jack Powers | |||
- Contact information: 9 Judge and Jury Drive, Lower Shotover (Queenstown), 9304, New Zealand | |||
- Phone: unknown | |||
- Email: jackthesparrow@gmail.com | |||
Player 3 | |||
- Name: Elizabeth Maltby | |||
- Contact information: 237 Fernhill Road, Fernhill (Queenstown), 7050, New Zealand | |||
- Phone: +64(029)5280754 | |||
- Email: zibbaree123@gmail.com | |||
Add the new team and its players into the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Add new country (team and its players) | |||
CALL INSERT_countryValues('tournament_db', 'COUNTRY', 'id_a3', 'NZ', 'NZL', '64', 'New Zealand'); | |||
-- 1) Add new postal codes (team and its players) | |||
INSERT INTO CITY (postalcode, country_id, name) VALUES | |||
('6011', 'NZ', 'Wellington'), | |||
('9348', 'NZ', 'Boydtown'), | |||
('9304', 'NZ', 'Lower Shotover'), | |||
('7050', 'NZ', 'Fernhill') | |||
; | |||
-- 3) Add the new team | |||
INSERT INTO TEAM (id, name, email, phone, postalcode, street, housenumber, IBAN, SWIFT_bank, SWIFT_number) VALUES | |||
('J010', 'Mahokara Team', 'mahorakateam@gmail.com', NULL, '6011', 'Majoribanks Street', '16', NULL, 'ANZBNZ22058', '05835020297713') | |||
; | |||
-- 4) Add the new players, link to the new team | |||
INSERT INTO PLAYER (id, team_id, firstname, lastname, email, phone, postalcode, street, housenumber) VALUES | |||
('P024', 'J010', 'Alyssa', 'Trickett', 'mohokai96@outlook.com', '+64(027)5721709', '9348', 'Edinburgh Drive', '50'), | |||
('P025', 'J010', 'Jack', 'Powers', 'jackthesparrow@gmail.com', NULL, '9304', 'Judge and Jury Drive', '9'), | |||
('P026', 'J010', 'Elizabeth', 'Maltby', 'zibbaree123@gmail.com', '+64(029)5280754', '7050', 'Fernhill Road', '237') | |||
; | |||
-- 5) Add team global ranking: new row to TEAM_RANK_GLOBAL table | |||
-- In real case, this information is fetched from external source | |||
-- and added programmatically to the tournament database | |||
INSERT INTO TEAM_RANK_GLOBAL (rank, team_id) VALUES | |||
(156, 'J010') | |||
; | |||
-- 6) Not adding: player ranks in the team | |||
-- Reason: Only participated players have this information in | |||
-- the tournament database. The added team has not played yet. | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 12 | |||
Organizer LFG Australia hires a new employee with the following information: | |||
- Name: Amy Rechner | |||
- Contact information: 44 Highmount Drive, Hampton Park (Melbourne), 3976, Australia | |||
- Phone: +61(08)82654779 | |||
- Email: amy.rechner@lfg-aus.com.au | |||
Add the new employee for the organizer in the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Add new postal code the the employee | |||
INSERT INTO CITY (postalcode, country_id, name) VALUES | |||
('3976', 'AU', 'Hampton Park') | |||
; | |||
-- 2) Add new employee information and link the employee to the organizer | |||
INSERT INTO ORG_EMPLOYEE (id, organizer_org_id, firstname, lastname, email, phone, postalcode, street, housenumber) VALUES | |||
('T021', 'O012', 'Amy', 'Rechner', 'amy.rechner@lfg-aus.com.au', '+61(08)82654779', '3976', 'Highmount Drive', '44') | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 13 | |||
Many teams have already retrieved a hint about the new tournament event "2020 NSW Family Tournaments" (added in task 10 above). The participating teams, which already have up-to-date information about themselves in the tournament database, are: | |||
- Mahokara Team | |||
- FreeRiders | |||
- Red Hats | |||
Not only the teams have heard about the coming up event: two hardcore fans have also heard rumors about it from multiple players. As passionate gamblers, they want to bet on their favorite teams on the event. However, they have not registered on the tournament platform. Some of the players tell these fans about the betting opportunity after which they hurry up signing up to the tournament platform. | |||
Bettor 1 bets only on his/her favorite team. Bettor 2 bets not only on his/her favorite team but also on the the same team than bettor 1 did. | |||
Bettor information is as follows: | |||
Bettor 1 | |||
- User name: Ratishda | |||
- Name: Zossima Gorbunov | |||
- Email: zosgorb@gmail.com | |||
- Phone: +7(8442)443225 | |||
- Password: private4Scape (64b4455db5e4fd242a22e8ea5e57b15850be4cfc3a7e58f432013723d7053677a472235c07b9cc7b08d504dfc607758bac3a073e103843144bc880166ae8662d) | |||
- SWIFT bank: JSBSRU2PXXX | |||
- SWIFT account number: 027807458042622 | |||
Betting information: | |||
- Favorite team: Red Hats | |||
- Guessed team rank: 1 | |||
- Betting multiplier: 3.22 | |||
- Initial money for betting: 425 (euro) | |||
- Betting status: accepted | |||
Bettor 2 | |||
- User name: Tiakakuna | |||
- Name: Harrison Brier | |||
- Email: harrkuna@gmail.com | |||
- Phone: unknown | |||
- Password: karakuna (4eef0fa919697f77cbd13179a90c9e0d90e15f127362c6d70161689e49fb79a1ac12b33efd128493870daa3b6918c68d0838501f73fbfbd1bccfc7faa01c5d29) | |||
- SWIFT bank: BKIDNZ2A | |||
- SWIFT account number: 26387479571396 | |||
Betting information 1: | |||
- Team: Mahokara Team | |||
- Guessed team rank: 1 | |||
- Betting multiplier: 7.88 | |||
- Initial money for betting: 50 (euro) | |||
- Betting status: queued for approval | |||
Betting information 2: | |||
- Team: FreeRiders | |||
- Guessed team rank: 3 | |||
- Betting multiplier: 9.5 | |||
- Initial money for betting: 230 (euro) | |||
- Betting status: queued for approval | |||
Link the mentioned teams to the tournament event. Add new bettors and their information, and add their betting information using the above input. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Add the teams to the TEAM_STATUS table. Since the event has not yet occured, we mark the teams as registered ones. | |||
INSERT INTO TEAM_STATUS (team_id, event_id, team_status, rank) VALUES | |||
('J010', 'E005', 'registered', NULL), | |||
('J003', 'E005', 'registered', NULL), | |||
('J004', 'E005', 'registered', NULL) | |||
; | |||
-- 2) Add the new bettors | |||
INSERT INTO BETTOR (id, firstname, lastname, email, phone, IBAN, SWIFT_bank, SWIFT_number, password) VALUES | |||
('Ratishda', 'Zossima', 'Gorbunov', 'zosgorb@gmail.com', '+7(8442)443225', NULL, 'JSBSRU2PXXX', '027807458042622', | |||
'64b4455db5e4fd242a22e8ea5e57b15850be4cfc3a7e58f432013723d7053677a472235c07b9cc7b08d504dfc607758bac3a073e103843144bc880166ae8662d'), | |||
('Tiakakuna', 'Harrison', 'Brier', 'harrkuna@gmail.com', NULL, NULL, 'BKIDNZ2A', '26387479571396', | |||
'4eef0fa919697f77cbd13179a90c9e0d90e15f127362c6d70161689e49fb79a1ac12b33efd128493870daa3b6918c68d0838501f73fbfbd1bccfc7faa01c5d29') | |||
; | |||
-- 3) Add the new betting information | |||
INSERT INTO BETTING (bettor_id, event_id, team_id, team_rank_guess, multiplier, initmoney, betstatus) VALUES | |||
('Ratishda', 'E005', 'J004', 1, 3.22, 425, 'accepted'), | |||
('Tiakakuna', 'E005', 'J010', 1, 7.88, 50, 'queued for approval'), | |||
('Tiakakuna', 'E005', 'J003', 3, 9.5, 230, 'queued for approval') | |||
; | |||
-- NOTE! Some of the given input values would automatically be generated | |||
-- in a program logic |
@ -0,0 +1,161 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 14 | |||
Logged in russian player Myron Ponomarev has moved away from his old home region. Therefore, he wants to update his contact information. | |||
The tournament platform has a web-based front-end which connects indirectly to the back-end servers. The player can change his information only via this web interface. | |||
The player types the following information as input: | |||
- postal code: 141300 | |||
- postal district: Северный | |||
- street: улица Чапаева | |||
- house number: 22 | |||
The country code does not change and stays locked in selection "Russia". | |||
After clicking "Accept" and checking permissions and validity of the updated information, the database server performs operations according to program logic. | |||
Do these operations manually to the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
/* Adding new city information for Russia */ | |||
INSERT INTO CITY (postalcode, country_id, name) VALUES | |||
('141300', 'RU', 'Северный'); | |||
UPDATE PLAYER | |||
SET | |||
postalcode = '141300', | |||
street = 'улица Чапаева', | |||
housenumber = '22' | |||
WHERE | |||
id = 'P010' AND | |||
firstname = 'Myron' AND | |||
lastname = 'Ponomarev' | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 15 | |||
Already registered game tournament DnDSports is wanted to be organized just under christmas 2019. Due to this sudden demand, the event period is shifted 24 days backwards. To gain more value for the event and to reduce criticism the event time is also extended by 2 days. | |||
Due to christmas season the additional information is updated. The new information reads: | |||
'Challenge top teams in this online gaming event and win your place! This event has also christmas magic for everyone!' | |||
Due to extended duration and additional christmas value participation fee is increased by 10 euros compared to the current fee. | |||
Apply these changes to the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
UPDATE GAME_EVENT | |||
SET | |||
/* MySQL */ | |||
starttime = DATE_ADD(starttime, INTERVAL '-12' DAY), | |||
endtime = DATE_ADD(endtime, INTERVAL '-10' DAY), | |||
/* SQL Server */ | |||
-- starttime = DATEADD(DAY, -12, starttime), | |||
-- endtime = DATEADD(DAY, -10, endtime) | |||
event_fee = (event_fee + 10), | |||
extrainfo = CONCAT(extrainfo, ' This event has also christmas magic for everyone!') | |||
WHERE | |||
id = 'E003' AND | |||
name = 'DnDSports' | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 16 | |||
Finnish team Rollihaukat played in DnD Rogue Challenge tournament. Their initial ranking was set to 3. However, after the event it was noticed that there was happened a mistake during result calculation. After correcting the results, it was found out that Rollihaukat actually won the event. There were other teams in the event, as well. One of them, swedish Vita Frost Bringararna, was ranked to the first place before the mistake was noticed. Instead, the swedish team took the second place. | |||
There were possibility to bet on favorite teams. One bettor, known as ForceWeaver, bet on Rollihaukat to win the event. Due to mistake, the bettor was informed that he/she was lost which was not actually the case, as it was discovered later. | |||
The game organizer sent apologies for all participants and the error was corrected very quickly. The swedish team was also informed about changes in the ranking order. The bettor got his/her prize money and teams their honor, respectfully. | |||
Other human errors were discovered, as well: information about russian team Red Hats was totally missing. The russian team took the third place after error corrections were made. Brazilian team Comedores de Caveira aborted during the event and dropped from ranking. | |||
Fix the data errors described above. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Update Rollihaukat ranking to value 1 in DnD Rogue Challenge event | |||
UPDATE TEAM_STATUS | |||
SET rank = 1 | |||
WHERE team_id = 'J001' AND event_id = 'E001' | |||
; | |||
-- 2) Update Vita Frost Bringararna ranking to value 2 in DnD Rogue Challenge event | |||
UPDATE TEAM_STATUS | |||
SET rank = 2 | |||
WHERE team_id = 'J006' AND event_id = 'E001' | |||
; | |||
-- 3) Add ranking information of team Red Hats in DnD Rogue Challenge event | |||
-- Ranking value is 3. | |||
INSERT INTO TEAM_STATUS (team_id, event_id, team_status, rank) VALUES | |||
('J004', 'E001', 'ranked', 3) | |||
; | |||
-- 4) Change betstatus of ForceWeaver to value 'won' in the DnD Rogue Challenge event | |||
UPDATE BETTING | |||
SET betstatus = 'won' | |||
WHERE | |||
bettor_id = 'ForceWeaver' AND | |||
event_id = 'E001' AND | |||
team_id = 'J001' | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 17 | |||
Employee Adrían Guzmán who works for Argentinean organizer Organización de mejora de nivel gets married. The happy event means his surname changes and he moves away from his current home town. Therefore, his postal code and street address change, too. | |||
Due to these radical changes in his life, he gets employed and works for brazilian tournament organization Associação Sul-Americana de Jogos de Tabuleiro. | |||
After all, he updates his contact information. The new information is: | |||
- Name: Adrían Fernanda Quezada | |||
- Contact information: Delfín 38, Toay, 6303, Argentina | |||
This information is being updated in the tournament database. Apply the changes manually. | |||
*/ | |||
-- ----------------------------------------------------- | |||
INSERT INTO CITY (postalcode, country_id, name) VALUES | |||
('6303', 'AR', 'Toay') | |||
; | |||
UPDATE ORG_EMPLOYEE | |||
SET | |||
organizer_org_id = 'O008', | |||
lastname = 'Fernanda Quezada', | |||
postalcode = '6303', | |||
street = 'Delfín', | |||
housenumber = '38' | |||
WHERE id = 'T013' | |||
; |
@ -0,0 +1,197 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 18 | |||
Iranian team, known internationally as BattleBrothers, has been temporarily banned from tournament events due to policy violation in an event held in another tournament platform. | |||
Our tournament database has an unexpected issue: we do not have any information regarding to team license or whether teams are allowed to play in events. This was not considered during database development phase. | |||
Because the ban is given by the top global tournament organization Boardgame Players Association and the company does not want to run out from business due to a silly mistake, the company board orders database administators to make proper changes to current database structure immediately. The license status must be placed in a way or another. During the ban period, no event fees are being allowed from the banned team. | |||
The database administrators try to adapt to the changed situation and work in pressure. They need to make sure that database integrity will not be broken in any case which is why full database backup is taken before necessary changes. | |||
After the database structure changes and successful tests one of the administrators inform the company board that necessary updates have been made. Additionally, the information was delivered to programming department in the company. | |||
The corporate communications officer informs the global tournament organization that the situation is under control and the company has made required adaptions to the tournament platform. | |||
During the database structure update the administators decided to make further improvements and add gaming license status information for each team in the database. | |||
After the procedures the database diagrams & formulas were updated in addition to database integrity and normalization checks. | |||
Apply all database changes described above with proper SQL queries (excluding normalization, diagrams and formulas). | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Remove BattleBrothers from TEAM_RANK_GLOBAL table | |||
DELETE FROM TEAM_RANK_GLOBAL | |||
WHERE team_id = 'J009' | |||
; | |||
-- 2) Add new column 'game_license' into TEAM table | |||
-- The column data type is NVARCHAR(20) NOT NULL | |||
-- Accepted values are: 'active', 'archived' and 'banned' | |||
-- Add the new column and a default value | |||
ALTER TABLE TEAM | |||
ADD game_license NVARCHAR(20) NOT NULL DEFAULT('active') AFTER name | |||
; | |||
-- MariaDB 10.2 implements CHECK constraints | |||
-- https://mariadb.com/kb/en/library/changes-improvements-in-mariadb-102/ | |||
-- Determine your version with query: SELECT @@version | |||
/* MySQL */ | |||
ALTER TABLE TEAM | |||
ADD CHECK( | |||
game_license = 'active' OR | |||
game_license = 'archived' OR | |||
game_license = 'banned' | |||
); | |||
/* SQL Server */ | |||
/* | |||
ALTER TABLE TEAM | |||
ALTER COLUMN game_license WITH CHECK( | |||
game_license = 'active' OR | |||
game_license = 'archived' OR | |||
game_license = 'banned' | |||
); | |||
*/ | |||
UPDATE TEAM | |||
SET game_license = 'banned' WHERE id = 'J009'; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 19 | |||
The database company board decided that to improve the use experience and obtain more valuable data, bettors should be able to add their personal contact information to the tournament platform via web interface. The order caused many kind of operations in programming and database departments. Database administrators were tasked to add support and change database structure so that web developers could implement changes to web front-end. | |||
The new information should be determined before bettor's password information (password column must be the last one). | |||
Apply required changes to the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
ALTER TABLE BETTOR | |||
ADD COLUMN postalcode VARCHAR(10) NULL AFTER phone, | |||
ADD COLUMN street NVARCHAR(80) NULL AFTER postalcode, | |||
ADD COLUMN housenumber NVARCHAR(7) NULL AFTER street | |||
; | |||
/* Removal with the following query | |||
ALTER TABLE BETTOR | |||
DROP COLUMN housenumber, | |||
DROP COLUMN street, | |||
DROP COLUMN postalcode | |||
; | |||
*/ | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 20 | |||
During brain storming meetings it was noted that the current database does not support three-letter country codes. The company board wants support for three-letter country codes. | |||
During the task, database administrators understood that as further improvement, it would be handy to have phone country prefix numbers directly among the other country data. The administrators implemented this extra feature although it was not utilized due to missing web application support. | |||
Apply the reservation for new three-letter country codes. Add new country codes for each country in the database. Implement support for country-speficic phone number suffixes. Add new number suffixes. | |||
What kind of difficult issues these changes can introduce to the database structure? | |||
The database administrators used the following website as their information source for the new data: | |||
https://www.worldatlas.com/aatlas/ctycodes.htm | |||
*/ | |||
-- ----------------------------------------------------- | |||
/* | |||
Adding condition NOT NULL does not work | |||
Phone numbers can't be unique, check UPDATE values below | |||
*/ | |||
ALTER TABLE COUNTRY | |||
ADD COLUMN id_a3 CHAR(3) UNIQUE AFTER id, | |||
ADD COLUMN dialing_code VARCHAR(5) AFTER id_a3 | |||
; | |||
UPDATE COUNTRY SET id_a3 = 'FIN', dialing_code = '358' WHERE id = 'FI'; | |||
UPDATE COUNTRY SET id_a3 = 'NOR', dialing_code = '47' WHERE id = 'NO'; | |||
UPDATE COUNTRY SET id_a3 = 'USA', dialing_code = '1' WHERE id = 'US'; | |||
UPDATE COUNTRY SET id_a3 = 'DEU', dialing_code = '49' WHERE id = 'DE'; | |||
UPDATE COUNTRY SET id_a3 = 'RUS', dialing_code = '7' WHERE id = 'RU'; | |||
UPDATE COUNTRY SET id_a3 = 'EST', dialing_code = '372' WHERE id = 'EE'; | |||
UPDATE COUNTRY SET id_a3 = 'JPN', dialing_code = '81' WHERE id = 'JP'; | |||
UPDATE COUNTRY SET id_a3 = 'ARG', dialing_code = '54' WHERE id = 'AR'; | |||
UPDATE COUNTRY SET id_a3 = 'ISL', dialing_code = '354' WHERE id = 'IS'; | |||
UPDATE COUNTRY SET id_a3 = 'AUT', dialing_code = '43' WHERE id = 'AT'; | |||
UPDATE COUNTRY SET id_a3 = 'BRA', dialing_code = '55' WHERE id = 'BR'; | |||
UPDATE COUNTRY SET id_a3 = 'DNK', dialing_code = '45' WHERE id = 'DK'; | |||
UPDATE COUNTRY SET id_a3 = 'SWE', dialing_code = '46' WHERE id = 'SE'; | |||
UPDATE COUNTRY SET id_a3 = 'IRN', dialing_code = '98' WHERE id = 'IR'; | |||
UPDATE COUNTRY SET id_a3 = 'MLT', dialing_code = '356' WHERE id = 'MT'; | |||
UPDATE COUNTRY SET id_a3 = 'PRI', dialing_code = '1' WHERE id = 'PR'; | |||
UPDATE COUNTRY SET id_a3 = 'SVN', dialing_code = '386' WHERE id = 'SI'; | |||
UPDATE COUNTRY SET id_a3 = 'VNM', dialing_code = '84' WHERE id = 'VN'; | |||
INSERT INTO COUNTRY (id, id_a3, dialing_code, name) VALUES | |||
('FR', 'FRA', '33', 'France') ON DUPLICATE KEY | |||
UPDATE id_a3 = 'FRA', dialing_code = '33' | |||
; | |||
INSERT INTO COUNTRY (id, id_a3, dialing_code, name) VALUES | |||
('AU', 'AUS', '61', 'Australia') ON DUPLICATE KEY | |||
UPDATE id_a3 = 'AUS', dialing_code = '61' | |||
; | |||
INSERT INTO COUNTRY (id, id_a3, dialing_code, name) VALUES | |||
('NZ', 'NZL', '64', 'New Zealand') ON DUPLICATE KEY | |||
UPDATE id_a3 = 'NZL', dialing_code = '64' | |||
; | |||
/* | |||
Change to NOT NULL after empty values have been filled. | |||
NOTE! This operation can cause issues so not all rows are filled | |||
beforehand. | |||
*/ | |||
/* SQL Server */ | |||
-- ALTER TABLE COUNTRY | |||
-- ALTER COLUMN id_a3 CHAR(3) NOT NULL, | |||
-- ALTER COLUMN dialing_code VARCHAR(5) NOT NULL; | |||
/* MySQL */ | |||
ALTER TABLE COUNTRY | |||
MODIFY id_a3 CHAR(3) NOT NULL, | |||
MODIFY dialing_code VARCHAR(5) NOT NULL | |||
; | |||
-- What kind of difficult issues these changes can introduce to the database structure? | |||
/* | |||
Answer: | |||
Additional columns can cause issues in country code usage | |||
since, after updates, two alternative country code formats | |||
exist. The current primary key COUNTRY.id does not really | |||
determine the country code format (2-letter or 3-letter). | |||
Better name for this column could be 'id_a2' but this change | |||
could break reference key structure in CITY table if | |||
necessary changes will not be made. | |||
The additional country code adds complexity for potential | |||
references: which country code format should reference keys | |||
actually refer to? | |||
*/ |
@ -0,0 +1,363 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
Delete specific rows from selected and pre-existing | |||
tables in the selected database. | |||
Be careful not to break relations & integrity of | |||
the database (primary & foreign key relations) | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 21 | |||
Tournament event Gamescom 2020 is cancelled. Privileged database administrator must delete the event from the database. Possible reasons for the cancellation are, for instance: | |||
- event organizer bankrupts | |||
- event does not get enough attraction and event organizer cancels the event | |||
Since the event has received participation fees and several other profits, they must be refunded using various APIs. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Delete event reservation | |||
DELETE RESERVATION FROM RESERVATION, CLUBROOM | |||
JOIN GAME_EVENT P | |||
ON P.clubroom_id = CLUBROOM.id | |||
WHERE | |||
RESERVATION.clubroom_id = P.clubroom_id AND | |||
P.id = 'E004' | |||
; | |||
-- 2) Delete event arrangement information | |||
DELETE ARRANGEMENT FROM ARRANGEMENT | |||
JOIN GAME_EVENT P | |||
ON P.id = ARRANGEMENT.event_id | |||
WHERE | |||
P.id = 'E004' | |||
; | |||
-- 3) Delete team status information from the event | |||
DELETE TEAM_STATUS FROM TEAM_STATUS | |||
JOIN GAME_EVENT P | |||
ON P.id = TEAM_STATUS.event_id | |||
WHERE | |||
P.id = 'E004' | |||
; | |||
-- 4) Delete event betting information | |||
DELETE BETTING FROM BETTING | |||
JOIN GAME_EVENT P | |||
ON P.id = BETTING.event_id | |||
WHERE | |||
P.id = 'E004' | |||
; | |||
-- 5) Delete the event | |||
DELETE FROM GAME_EVENT | |||
WHERE id = 'E004'; | |||
/* | |||
Other, more user-friendlier way to show information | |||
regarding to a cancelled event would be better | |||
utilization of the existing web interface. | |||
The interface could have event status information | |||
'cancelled'. In the current database, table GAME_EVENT | |||
could have a suitable attribute [status] for this information. | |||
*/ | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 22 | |||
As a result of the ban, iranian team BattleBrothers is deleted from the tournament database. The team and related data is simply deleted. Optional reasons for permanent deletion could be: | |||
- team has not been active for a long time | |||
- team breaks up or ceases to exist | |||
Before the actual deletion existing team data should be archived via suitable APIs and using another archive database. The simple programming logic could be: WHEN team data is archived THEN delete the data from the tournament database. Archived data may help if any further confict will arise later on. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Team data is linked to multiple tables in the tournament database. Thus, the deletion is progressive, as shown below. | |||
USE tournament_db; | |||
-- 1) Delete team-specific player ranking information | |||
DELETE PLAYER_RANK FROM PLAYER_RANK | |||
JOIN TEAM J | |||
ON PLAYER_RANK.team_id = J.id | |||
WHERE | |||
J.id = 'J009' | |||
; | |||
-- 2) Delete team players | |||
DELETE PLAYER FROM PLAYER | |||
JOIN TEAM J | |||
ON PLAYER.team_id = J.id | |||
WHERE | |||
J.id = 'J009' | |||
; | |||
-- 3) Delete team event status information | |||
DELETE TEAM_STATUS FROM TEAM_STATUS | |||
JOIN TEAM J | |||
ON TEAM_STATUS.team_id = J.id | |||
WHERE | |||
J.id = 'J009' | |||
; | |||
-- 4) Delete team global ranking information | |||
DELETE TEAM_RANK_GLOBAL FROM TEAM_RANK_GLOBAL | |||
JOIN TEAM J | |||
ON TEAM_RANK_GLOBAL.team_id = J.id | |||
WHERE | |||
J.id = 'J009' | |||
; | |||
-- 5) Delete team-related betting information | |||
DELETE BETTING FROM BETTING | |||
JOIN TEAM J | |||
ON BETTING.team_id = J.id | |||
WHERE | |||
J.id = 'J009' | |||
; | |||
-- 6) Delete the team from the database | |||
DELETE FROM TEAM WHERE id = 'J009'; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 23 | |||
Russian organizer северные медведи bankrupts. Once the news reach the tournament company, database administrators take an action to delete information related to the organizer. The organizer and all related data is deleted. | |||
Other reasons for deleting an organizer could be a fusion of multiple organizers. | |||
NOTE: | |||
Before the actual data removal it would be encouraged to back it up and clone, for instance, to another archival database. | |||
Basically, the proceduce could be as follows: WHEN organization information is archived, THEN delete the data from this database. Archived data could help in indisputability of the data validity if it's ever needed afterwards. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Organizer data is linked to multiple tables in the tournament database. Thus, the deletion is progressive, as shown below. | |||
-- 1) Delete organizer employee information | |||
DELETE ORG_EMPLOYEE FROM ORG_EMPLOYEE | |||
JOIN ORGANIZER_ORG J | |||
ON ORG_EMPLOYEE.organizer_org_id = J.id | |||
WHERE | |||
J.id = 'O004' | |||
; | |||
-- 2) Delete reservations by the organizer | |||
DELETE RESERVATION FROM RESERVATION | |||
JOIN ORGANIZER_ORG J | |||
ON RESERVATION.organizer_org_id = J.id | |||
WHERE | |||
J.id = 'O004' | |||
; | |||
-- 3) Delete tournament arrangement information | |||
-- by the organizer | |||
DELETE ARRANGEMENT FROM ARRANGEMENT | |||
JOIN ORGANIZER_ORG J | |||
ON ARRANGEMENT.organizer_org_id = J.id | |||
WHERE | |||
J.id = 'O004' | |||
; | |||
-- 4) Delete the organizer from the database | |||
DELETE FROM ORGANIZER_ORG WHERE id = 'O004'; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 24 | |||
Bettor nicknamed as Katoteshi has cheated and his/her actions have led to a criminal investigation due to not returned win prizes he/she has received. Due to cheating all logged actions and old/new account information is backed up which helps in the investigation. Once the criminal investigation is started, the bettor is deleted from the tournament database. | |||
In general, other reasons for account deletion could be | |||
- supplying false information | |||
- general cheating | |||
- very long inactivity time | |||
Tournament database administrators get a task to delete the bettor from the database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Delete betting information related to the bettor | |||
DELETE FROM BETTING WHERE bettor_id = 'Katoteshi'; | |||
-- 2) Delete the bettor | |||
DELETE FROM BETTOR WHERE id = 'Katoteshi'; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 25 | |||
Database company owning the tournament database has changed its terms of use for the tournament application platform. Major changes for players include requirement of having personal contact information connected to new and existing accounts. To be specific, the required information is: | |||
- phone number | |||
- postal code | |||
- street | |||
- house number | |||
Earlier this information was optional and only email information was required. | |||
A database administrator sends a group email to notify players about the changed terms of use. The administrator wants to send the email only for players lacking the required contact information to avoid spamming messages unnecessarily. The email message has a clearly stated deadline after which the database company reserves rights to delete player information from the tournament database unless the new terms of use conditions have been met. | |||
The database administrators obtain names of the players missing the required information with SQL SELECT queries. After deadline, the administrator executes DELETE queries. | |||
The following players have not added required contact information in required time: | |||
- Lạc Trọng Phu | |||
- Hàn Hữu Nghi | |||
- Lê Đình Hưng | |||
- Minan Ikegami | |||
Before delete operations the administrator archives related player data. An email is sent to the deleted players. These operations are excluded from this task. | |||
Apply the delete operations described above. | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- 1) Delete player's team-specific rank information | |||
DELETE PLAYER_RANK FROM PLAYER_RANK | |||
JOIN PLAYER P | |||
ON PLAYER_RANK.player_id = P.id | |||
WHERE | |||
(P.id = 'P012' AND P.firstname = 'Lạc' AND P.lastname = 'Trọng Phu'); | |||
DELETE PLAYER_RANK FROM PLAYER_RANK | |||
JOIN PLAYER P | |||
ON PLAYER_RANK.player_id = P.id | |||
WHERE | |||
(P.id = 'P020' AND P.firstname = 'Hàn' AND P.lastname = 'Hữu Nghi'); | |||
DELETE PLAYER_RANK FROM PLAYER_RANK | |||
JOIN PLAYER P | |||
ON PLAYER_RANK.player_id = P.id | |||
WHERE | |||
(P.id = 'P021' AND P.firstname = 'Lê' AND P.lastname = 'Đình Hưng'); | |||
DELETE PLAYER_RANK FROM PLAYER_RANK | |||
JOIN PLAYER P | |||
ON PLAYER_RANK.player_id = P.id | |||
WHERE | |||
(P.id = 'P004' AND P.firstname = 'Minan' AND P.lastname = 'Ikegami'); | |||
-- 2) Delete player information | |||
DELETE FROM PLAYER WHERE | |||
(id = 'P012' AND firstname = 'Lạc' AND lastname = 'Trọng Phu') OR | |||
(id = 'P020' AND firstname = 'Hàn' AND lastname = 'Hữu Nghi') OR | |||
(id = 'P021' AND firstname = 'Lê' AND lastname = 'Đình Hưng') OR | |||
(id = 'P004' AND firstname = 'Minan' AND lastname = 'Ikegami') | |||
; | |||
-- 3) NOTE! Team J005 remains without players. Because the team could have | |||
-- additional members in the future and it has valid ranking information, | |||
-- we shall not delete the team itself. | |||
-- However, after very long inactivity period the team deletion could be possible. | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 26 | |||
Tournament database administator want to purge unused, orphaned city information from the tournament database. To avoid unnecessary data bloat the cleaning operation is well justified. | |||
Delete unused cities and towns from the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
/* | |||
Bypass safe update check. Otherwise MySQL server returns | |||
an error regarding to failed delete operations. | |||
NOTE! This query has been tested and validated to be safe | |||
for database integrity and structure. | |||
*/ | |||
SET SQL_SAFE_UPDATES = 0; | |||
DELETE FROM CITY | |||
WHERE postalcode IN ( | |||
SELECT postalcode FROM ( | |||
SELECT CITY.* FROM ( | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM ORG_EMPLOYEE | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM ORGANIZER_ORG | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM PLAYER | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM TEAM | |||
UNION | |||
SELECT DISTINCT | |||
postalcode AS postalcode_used | |||
FROM CLUBROOM | |||
) USED_ZIPCODES | |||
RIGHT JOIN CITY ON | |||
USED_ZIPCODES.postalcode_used = CITY.postalcode | |||
WHERE USED_ZIPCODES.postalcode_used IS NULL | |||
) UNUSED_ZIPCODES | |||
) | |||
; | |||
-- ----------------------------------------------------- | |||
/* | |||
ASSIGNMENT 27 | |||
Tournament database administator want to purge unused, orphaned country information from the tournament database. To avoid unnecessary data bloat the cleaning operation is well justified. | |||
Delete unused countries and country codes from the tournament database. | |||
*/ | |||
-- ----------------------------------------------------- | |||
/* | |||
Bypass safe update check. Otherwise MySQL server returns | |||
an error regarding to failed delete operations. | |||
NOTE! This query has been tested and validated to be safe | |||
for database integrity and structure. | |||
*/ | |||
SET SQL_SAFE_UPDATES = 0; | |||
DELETE FROM COUNTRY | |||
WHERE id IN ( | |||
SELECT id FROM ( | |||
SELECT COUNTRY.* FROM COUNTRY | |||
LEFT JOIN CITY ON | |||
COUNTRY.id = CITY.country_id | |||
WHERE CITY.name IS NULL | |||
) UNUSED_COUNTRIES | |||
) | |||
; |
@ -0,0 +1,250 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
-- USE tournament_db; | |||
-- ----------------------------------------------------- | |||
-- DATABASE USER ROLES | |||
-- | |||
-- NOTE: This query does not use query types of [CREATE, DROP] ROLE. | |||
-- NOTE: This query requires root permissions in the database server unless | |||
-- current non-root user has the following permissions: | |||
-- GRANT CREATE USER ON *.* TO '<non-root_user>'@'localhost' WITH GRANT OPTION | |||
-- | |||
-- Create new SQL server users. Server uses local DNS address 'localhost' | |||
-- | |||
-- IDENTIFIED BY field defines user password as plain text | |||
-- Administration users | |||
CREATE USER IF NOT EXISTS 'superadmin'@'localhost' IDENTIFIED BY 'supersecretpasswd'; | |||
CREATE USER IF NOT EXISTS 'loweradmin'@'localhost' IDENTIFIED BY 'lesssecretpasswd'; | |||
-- Normal users | |||
-- Player, employee and bettor must re-define their passwords next time they log in. | |||
CREATE USER IF NOT EXISTS 'player'@'localhost' IDENTIFIED BY 'playerpasswd' PASSWORD EXPIRE; | |||
CREATE USER IF NOT EXISTS 'employee'@'localhost' IDENTIFIED BY 'employeepasswd' PASSWORD EXPIRE; | |||
CREATE USER IF NOT EXISTS 'bettor'@'localhost' IDENTIFIED BY 'bettorpasswd' PASSWORD EXPIRE; | |||
-- ----------------------------------------------------- | |||
-- SUPER ADMIN | |||
-- Higher administrator has all permissions granted and can administrate | |||
-- permissions of others. | |||
GRANT ALL PRIVILEGES ON tournament_db.* TO 'superadmin'@'localhost' | |||
WITH GRANT OPTION; | |||
-- ----------------------------------------------------- | |||
-- ADMIN | |||
-- Lower administrator has access to all tables except for COUNTRY and CITY | |||
-- from which he/she can't delete any rows. | |||
-- Can't administate permissions of others. | |||
-- GRANT ALL PRIVILEGES ON tournament_db.* TO 'loweradmin'@'localhost'; | |||
GRANT SELECT, INSERT, UPDATE ON tournament_db.COUNTRY TO 'loweradmin'@'localhost'; | |||
GRANT SELECT, INSERT, UPDATE ON tournament_db.CITY TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.TEAM TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.PLAYER TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.ORGANIZER_ORG TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.ORGANIZER_EMPLOYEE TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.CLUBROOM TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.EVENT TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.RESERVATION TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.ARRANGEMENT TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.TEAM_STATUS TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.PLAYER_RANK TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.TEAM_RANK_GLOBAL TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.BETTOR TO 'loweradmin'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.BETTING TO 'loweradmin'@'localhost'; | |||
-- REVOKE DELETE ON tournament_db.COUNTRY FROM 'loweradmin'@'localhost'; | |||
-- REVOKE DELETE ON CITY FROM 'loweradmin'@'localhost'; | |||
-- ----------------------------------------------------- | |||
-- PLAYER (in a TEAM) | |||
-- COUNTRY: limited, undirect data representation via API | |||
-- CITY: limited, undirect data representation via API | |||
-- Select and update (only) for own TEAM information | |||
-- More fine grained role classification in a TEAM could be a player | |||
-- with permissions to remove TEAM-related information. | |||
GRANT SELECT, UPDATE ON tournament_db.TEAM TO 'player'@'localhost'; | |||
-- All permissions (only) to own information | |||
-- | |||
-- NOTE! Unimplemented feature: limit access to "own information only" | |||
GRANT ALL PRIVILEGES ON tournament_db.PLAYER TO 'player'@'localhost'; | |||
-- PLAYER can observe the following table data | |||
GRANT SELECT ON tournament_db.ORGANIZER_ORG TO 'player'@'localhost'; | |||
GRANT SELECT ON tournament_db.EVENT TO 'player'@'localhost'; | |||
GRANT SELECT ON tournament_db.TEAM_STATUS TO 'player'@'localhost'; | |||
GRANT SELECT ON tournament_db.TEAM_RANK_GLOBAL TO 'player'@'localhost'; | |||
-- PLAYER can observe only his/her own ranking information | |||
-- NOTE! Unimplemented feature: limit access to "own information only" | |||
GRANT SELECT ON tournament_db.PLAYER_RANK TO 'player'@'localhost'; | |||
-- PLAYER shall not have any permissions to the following tables. | |||
-- | |||
-- Although these permissions have not been granted in the first place, | |||
-- the REVOKE commands are demonstrated here. | |||
-- | |||
-- REVOKE ALL ON tournament_db.ORGANIZER_EMPLOYEE FROM 'player'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.CLUBROOM FROM 'player'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.RESERVATION FROM 'player'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.ARRANGEMENT FROM 'player'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.BETTOR FROM 'player'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.BETTING FROM 'player'@'localhost'; | |||
-- ----------------------------------------------------- | |||
-- EMPLOYEE (in an ORGANIZATION) | |||
-- COUNTRY: limited, undirect data representation via API | |||
-- CITY: limited, undirect data representation via API | |||
-- TEAM: limited, undirect data representation via API | |||
-- PLAYER: limited, undirect data representation via API | |||
-- Select and update (only) for own ORGANIZATION information | |||
-- More fine grained role classification in an ORGANIZATION could be an employee | |||
-- with permissions to remove ORGANIZATION-related information. | |||
GRANT SELECT, UPDATE ON tournament_db.ORGANIZER_ORG TO 'employee'@'localhost'; | |||
-- All permissions (only) to own information | |||
GRANT ALL PRIVILEGES ON tournament_db.ORGANIZER_EMPLOYEE TO 'employee'@'localhost'; | |||
-- Employee of an organization can select and update club room and game event information. | |||
GRANT SELECT, INSERT, UPDATE ON tournament_db.CLUBROOM TO 'employee'@'localhost'; | |||
GRANT SELECT, INSERT, UPDATE ON tournament_db.EVENT TO 'employee'@'localhost'; | |||
-- Employee of an organization has access to all event arrangement information | |||
-- regarding to his/her own organization. | |||
GRANT ALL PRIVILEGES ON tournament_db.RESERVATION TO 'employee'@'localhost'; | |||
GRANT ALL PRIVILEGES ON tournament_db.ARRANGEMENT TO 'employee'@'localhost'; | |||
-- Employee of an organization can observe global ranking information of teams. | |||
GRANT SELECT ON tournament_db.TEAM_RANK_GLOBAL TO 'employee'@'localhost'; | |||
-- Employee of an organization can select and update betting information regarding | |||
-- to bettor status information in a case the bettor is participating to | |||
-- an event arranged by the organization. | |||
-- NOTE! Unimplemented feature: limit access to "own information only" | |||
GRANT SELECT, UPDATE (voittostatus) ON tournament_db.BETTING TO 'employee'@'localhost'; | |||
-- EMPLOYEE shall not have any permissions to the following tables. | |||
-- | |||
-- Although these permissions have not been granted in the first place, | |||
-- the REVOKE commands are demonstrated here. | |||
-- | |||
-- REVOKE ALL ON tournament_db.TEAM_STATUS FROM 'employee'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.PLAYER_RANK FROM 'employee'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.BETTOR FROM 'employee'@'localhost'; | |||
-- ----------------------------------------------------- | |||
-- BETTOR | |||
-- COUNTRY: limited, undirect data representation via API | |||
-- CITY: limited, undirect data representation via API | |||
-- TEAM: limited, undirect data representation via API | |||
-- Select (only) for related CLUBROOM information. | |||
-- Bettor can observe only information regarding to his/her team in a game event | |||
-- he/she is participating. | |||
-- NOTE! Unimplemented feature: limit access to "own information only" | |||
GRANT SELECT ON tournament_db.CLUBROOM TO 'bettor'@'localhost'; | |||
GRANT SELECT ON tournament_db.TEAM_STATUS TO 'bettor'@'localhost'; | |||
-- Bettor can check all available and upcoming game events | |||
-- for betting purposes. | |||
GRANT SELECT ON tournament_db.EVENT TO 'bettor'@'localhost'; | |||
-- Bettor can observe global ranking of a team which helps him/her to place | |||
-- a bet for his/her favorite team in an event. | |||
GRANT SELECT ON tournament_db.TEAM_RANK_GLOBAL TO 'bettor'@'localhost'; | |||
-- Bettor can fully administrate his/her profile information. | |||
-- NOTE! Unimplemented feature: limit access to "own information only" | |||
GRANT ALL PRIVILEGES ON tournament_db.BETTOR TO 'bettor'@'localhost'; | |||
-- NOTE! Unimplemented feature: limit access to "own information only" | |||
-- NOTE! Additional program logic is required regarding to events | |||
-- and teams. This is because we need to check which possible event | |||
-- and team values a bettor can insert into the database/input fields. | |||
-- NOTE! Unimplemented feature: limit access to "own information only" | |||
-- Bettor has not permission to modify his/her unique identifier or | |||
-- BETTING win/lose status information. | |||
GRANT SELECT, INSERT, UPDATE (event_id, team_id, team_rank_guess, multiplier, initmoney) | |||
ON tournament_db.BETTING TO 'bettor'@'localhost'; | |||
-- BETTOR shall not have any permissions to the following tables. | |||
-- | |||
-- Although these permissions have not been granted in the first place, | |||
-- the REVOKE commands are demonstrated here. | |||
-- | |||
-- REVOKE ALL ON tournament_db.PLAYER FROM 'bettor'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.ORGANIZER_ORG FROM 'bettor'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.ORGANIZER_EMPLOYEE FROM 'bettor'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.RESERVATION FROM 'bettor'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.ARRANGEMENT FROM 'bettor'@'localhost'; | |||
-- REVOKE ALL ON tournament_db.PLAYER_RANK FROM 'bettor'@'localhost'; | |||
-- ----------------------------------------------------- | |||
-- Update database server privilege definitions | |||
-- FLUSH PRIVILEGES; | |||
-- ----------------------------------------------------- | |||
-- Validate permission configuration | |||
-- | |||
-- NOTE NOTE NOTE! | |||
-- The following SELECT query is not possible for a normal database user | |||
-- and a database server throws the following error message instead: | |||
-- Error Code: 1044. Access denied for user <user> to database 'mysql' | |||
-- | |||
-- Database server admin (with root permissions) should grant | |||
-- exceptional and temporary permissions for a trusted user to | |||
-- run the following queries. When granting special permissions, | |||
-- extra security precautions and protections should be considered | |||
-- for the server. | |||
SHOW GRANTS FOR 'superadmin'@'localhost'; | |||
SHOW GRANTS FOR 'loweradmin'@'localhost'; | |||
-- | |||
SHOW GRANTS FOR 'player'@'localhost'; | |||
SHOW GRANTS FOR 'employee'@'localhost'; | |||
SHOW GRANTS FOR 'bettor'@'localhost'; | |||
-- ----------------------------------------------------- | |||
-- DELETE USER ROLES | |||
-- | |||
-- Delete created users from the database server. | |||
-- These queries also delete user-specific, table-related | |||
-- privilege information. | |||
DROP USER 'superadmin'@'localhost'; | |||
DROP USER 'loweradmin'@'localhost'; | |||
DROP USER 'player'@'localhost'; | |||
DROP USER 'employee'@'localhost'; | |||
DROP USER 'bettor'@'localhost'; |
@ -0,0 +1,79 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
Delete data inserted in insert_testdata and in | |||
any other queries which are altered the database | |||
Deletion in reverse order (take constraints into | |||
consideration). | |||
*/ | |||
-- ----------------------------------------------------- | |||
-- Assumes that database 'tournament_db' exists | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
-- ----------------------------------------------------- | |||
-- Delete data for table BETTING | |||
DELETE FROM BETTING; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table BETTOR | |||
DELETE FROM BETTOR; | |||
-- ----------------------------------------------------- | |||
-- Delete for table TEAM_RANK_GLOBAL | |||
DELETE FROM TEAM_RANK_GLOBAL; | |||
-- ----------------------------------------------------- | |||
-- Delete for table PLAYER_RANK | |||
DELETE FROM PLAYER_RANK; | |||
-- ----------------------------------------------------- | |||
-- Delete for table TEAM_STATUS | |||
DELETE FROM TEAM_STATUS; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table ARRANGEMENT | |||
DELETE FROM ARRANGEMENT; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table RESERVATION | |||
DELETE FROM RESERVATION; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table EVENT | |||
DELETE FROM EVENT; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table CLUBROOM | |||
DELETE FROM CLUBROOM; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table ORGANIZER_EMPLOYEE | |||
DELETE FROM ORGANIZER_EMPLOYEE; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table ORGANIZER_ORG | |||
DELETE FROM ORGANIZER_ORG; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table PLAYER | |||
DELETE FROM PLAYER; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table TEAM | |||
DELETE FROM TEAM; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table CITY | |||
DELETE FROM CITY; | |||
-- ----------------------------------------------------- | |||
-- Delete data for table COUNTRY | |||
DELETE FROM COUNTRY; |
@ -0,0 +1,44 @@ | |||
/* | |||
MySQL SQL query script for Tournament database | |||
Designed for MariaDB RDBMS | |||
Author: | |||
Pekka Helenius <fincer89 [at] hotmail [dot] com> | |||
2019 | |||
*/ | |||
-- ----------------------------------------------------- | |||
/* Assumes that database 'tournament_db' exists */ | |||
USE tournament_db; | |||
-- ----------------------------------------------------- | |||
-- Drop tables in reverse order compared to CREATE TABLE | |||
-- due to foreign key constraints/(public key) relations | |||
-- ----------------------------------------------------- | |||
DROP TABLE IF EXISTS BETTING; | |||
DROP TABLE IF EXISTS BETTOR; | |||
DROP TABLE IF EXISTS TEAM_RANK_GLOBAL; | |||
DROP TABLE IF EXISTS PLAYER_RANK; | |||
DROP TABLE IF EXISTS TEAM_STATUS; | |||
DROP TABLE IF EXISTS ARRANGEMENT; | |||
DROP TABLE IF EXISTS RESERVATION; | |||
DROP TABLE IF EXISTS EVENT; | |||
DROP TABLE IF EXISTS CLUBROOM; | |||
DROP TABLE IF EXISTS ORGANIZER_EMPLOYEE; | |||
DROP TABLE IF EXISTS ORGANIZER_ORG; | |||
DROP TABLE IF EXISTS PLAYER; | |||
DROP TABLE IF EXISTS TEAM; | |||
DROP TABLE IF EXISTS CITY; | |||
DROP TABLE IF EXISTS COUNTRY; | |||
-- ----------------------------------------------------- | |||
-- Drop the database schema | |||
-- ----------------------------------------------------- | |||
DROP SCHEMA IF EXISTS tournament_db; |