This repository has been archived by the owner on Jan 22, 2022. It is now read-only.
-
Notifications
You must be signed in to change notification settings - Fork 2
/
Copy pathbasketball.sql
302 lines (222 loc) · 11.7 KB
/
basketball.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
/**
* Basketball League test database.
*
* Created for MySQL 8.0.19
*
* @author Martin Latter
* @copyright Martin Latter 09/12/2020
* @version 0.06
* @license GNU GPL version 3.0 (GPL v3); http://www.gnu.org/licenses/gpl.html
* @link https://github.com/Tinram/Database-Filler.git
*/
CREATE DATABASE `basketball` CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
USE `basketball`;
CREATE TABLE `country`
(
`country_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`country_code` CHAR(3) NOT NULL DEFAULT '' COMMENT '3-digit ISO code',
`country_name` VARCHAR(25) NOT NULL DEFAULT '',
UNIQUE KEY `uidx_country_code` (`country_code`),
PRIMARY KEY (`country_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `league`
(
`league_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`country_code` CHAR(3) NOT NULL DEFAULT '',
`name` VARCHAR(60) NOT NULL DEFAULT '' COMMENT 'e.g. LSBES – Liga Superior de Baloncesto de El Salvador',
`acronym` CHAR(3) NOT NULL DEFAULT '',
`gender` ENUM('M', 'F', 'O', '-') NOT NULL DEFAULT '-',
`tier` TINYINT UNSIGNED NOT NULL DEFAULT 0 COMMENT 'first tier, second tier, zero for unassigned',
`details` VARCHAR(255) NOT NULL DEFAULT '',
`img_src` VARCHAR(60) NOT NULL DEFAULT '' COMMENT 'server path for image file',
`active` TINYINT UNSIGNED NOT NULL DEFAULT 1,
`deleted` TINYINT UNSIGNED NOT NULL DEFAULT 0 COMMENT 'soft delete',
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
UNIQUE KEY `uidx_acronym` (`acronym`),
KEY `idx_active` (`active`),
KEY `idx_deleted` (`deleted`),
CONSTRAINT `fk_country_code` FOREIGN KEY (`country_code`) REFERENCES country (`country_code`) ON DELETE CASCADE ON UPDATE CASCADE,
PRIMARY KEY (`league_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `season`
(
`season_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`name` VARCHAR(30) NOT NULL DEFAULT '',
`duration` TINYINT UNSIGNED NOT NULL DEFAULT 7 COMMENT 'number of months in season',
`start_date` DATE NOT NULL,
`end_date` DATE NOT NULL,
`number_games` TINYINT UNSIGNED NOT NULL DEFAULT 0 COMMENT '82 max games in NBA',
`number_teams` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`archived` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
KEY `idx_archived` (`archived`),
PRIMARY KEY (`season_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `team`
(
`team_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`league_id` INT UNSIGNED NOT NULL,
`name` VARCHAR(30) NOT NULL DEFAULT '',
`acronym` CHAR(3) NOT NULL DEFAULT '',
`founded` SMALLINT UNSIGNED NOT NULL,
`captain` VARCHAR(20) NOT NULL DEFAULT '',
`coach` VARCHAR(20) NOT NULL DEFAULT '',
`logo_src` VARCHAR(60) NOT NULL DEFAULT '' COMMENT 'server path for image file',
`active` TINYINT UNSIGNED NOT NULL DEFAULT 1,
`deleted` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
UNIQUE KEY `uidx_acronym` (`acronym`),
KEY `idx_captain` (`captain`),
KEY `idx_active` (`active`),
KEY `idx_deleted` (`deleted`),
CONSTRAINT `fk_league` FOREIGN KEY (`league_id`) REFERENCES league (`league_id`) ON DELETE NO ACTION ON UPDATE NO ACTION,
PRIMARY KEY (`team_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `player`
(
`player_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`team_id` INT UNSIGNED NOT NULL,
`first_name` VARCHAR(35) NOT NULL,
`last_name` VARCHAR(35) NOT NULL,
`age` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`img_src` VARCHAR(60) NOT NULL DEFAULT '' COMMENT 'server path for image file',
`active` TINYINT UNSIGNED NOT NULL DEFAULT 1,
`deleted` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
KEY `idx_last_name` (`last_name`),
KEY `idx_name` (`first_name`, `last_name`),
KEY `idx_active` (`active`),
KEY `idx_deleted` (`deleted`),
CONSTRAINT `fk_p_team` FOREIGN KEY (`team_id`) REFERENCES team (`team_id`) ON DELETE NO ACTION ON UPDATE NO ACTION,
PRIMARY KEY (`player_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `game`
(
`game_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`date` DATE NOT NULL,
`venue` VARCHAR(40) NOT NULL DEFAULT '',
`details` VARCHAR(512) NOT NULL DEFAULT '',
`home` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`away` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`deleted` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
KEY `idx_date` (`date`),
KEY `idx_venue` (`venue`),
KEY `idx_deleted` (`deleted`),
PRIMARY KEY (`game_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT 'table game = matches';
CREATE TABLE `game_stats`
(
`game_stats_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`game_id` INT UNSIGNED NOT NULL,
`player_id` INT UNSIGNED NOT NULL,
`team_id` INT UNSIGNED NOT NULL,
`season_id` INT UNSIGNED NOT NULL,
`points_per_game` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`shots_on_goal` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`shots_missed` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`field_goals` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`field_goal_attempts` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`field_goal_pct` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`free_throws_made` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`free_throws_attempts` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`free_throw_pct` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`rebounds` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`offensive_rebounds` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`offensive_rebound_pct` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`defensive_rebounds` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`defensive_rebound_pct` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`attempts_in_paint` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`assists` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`steals` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`blocks` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`saves` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`fouls` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`turnovers` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`rating` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`efficiency` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`personal_fouls` SMALLINT UNSIGNED NOT NULL DEFAULT 0,
`minutes` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`performance_index_rating` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`deleted` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
KEY `idx_deleted` (`deleted`),
CONSTRAINT `fk_gs_game` FOREIGN KEY (`game_id`) REFERENCES game (`game_id`) ON DELETE CASCADE ON UPDATE CASCADE, -- if game deleted, delete stats
CONSTRAINT `fk_gs_player` FOREIGN KEY (`player_id`) REFERENCES player (`player_id`) ON DELETE NO ACTION ON UPDATE CASCADE, -- if player deleted, keep stats
CONSTRAINT `fk_gs_team` FOREIGN KEY (`team_id`) REFERENCES team (`team_id`) ON DELETE CASCADE ON UPDATE CASCADE, -- if team deleted, delete stats
CONSTRAINT `fk_gs_season` FOREIGN KEY (`season_id`) REFERENCES season (`season_id`) ON DELETE NO ACTION ON UPDATE CASCADE, -- if season deleted, keep stats
PRIMARY KEY (`game_stats_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT 'catch-all table for team, player results';
CREATE TABLE `article`
(
`article_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`title` VARCHAR(40) NOT NULL DEFAULT '',
`body` VARCHAR(8192) NOT NULL DEFAULT '' COMMENT 'inline, avoid TEXT',
`upload_date` DATE NOT NULL,
`category` ENUM('news', 'feature', 'archived', 'historical') NOT NULL DEFAULT 'news',
`active` TINYINT UNSIGNED NOT NULL DEFAULT 0 COMMENT 'default invisible until deployed',
`archived` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
UNIQUE KEY `uidx_title` (`title`),
FULLTEXT KEY `idx_body` (`body`),
KEY `idx_upload_date` (`upload_date`),
KEY `idx_act_cat_title` (`active`, `category`, `title`),
KEY `idx_category` (`category`),
KEY `idx_active` (`active`),
KEY `idx_archived` (`archived`),
KEY `idx_added` (`added`),
PRIMARY KEY (`article_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `user`
(
`user_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`first_name` VARCHAR(30) NOT NULL,
`last_name` VARCHAR(30) NOT NULL,
`user_name` VARCHAR(20) NOT NULL DEFAULT '',
`email` VARCHAR(50) NOT NULL DEFAULT '',
`password_hash` CHAR(60) NOT NULL COMMENT 'hash storage for bcrypt',
`active` TINYINT UNSIGNED NOT NULL DEFAULT 1,
`added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
`added_by` CHAR(16) NOT NULL DEFAULT '',
`updated` DATETIME DEFAULT NULL,
`updated_by` CHAR(16) NOT NULL DEFAULT '',
KEY `idx_first_name` (`first_name`),
KEY `idx_last_name` (`last_name`),
UNIQUE KEY `uidx_user_name` (`user_name`),
UNIQUE KEY `uidx_email` (`email`),
KEY `idx_active` (`active`),
PRIMARY KEY (`user_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;
CREATE TABLE `administration`
(
`administration_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`user_name` CHAR(16) NOT NULL DEFAULT '',
`password_hash` CHAR(60) NOT NULL,
`email` VARCHAR(50) NOT NULL DEFAULT '',
`admin_level` TINYINT UNSIGNED NOT NULL DEFAULT 1,
`active` TINYINT UNSIGNED NOT NULL DEFAULT 1,
UNIQUE KEY `uidx_user_name` (`user_name`),
KEY `idx_active` (`active`),
PRIMARY KEY (`administration_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT 'for internal administation';