-
Notifications
You must be signed in to change notification settings - Fork 12
/
schema.sql
419 lines (385 loc) · 16.4 KB
/
schema.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
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
CREATE TABLE IF NOT EXISTS `accounts` (
`id` int NOT NULL AUTO_INCREMENT,
`name` varchar(32) NOT NULL,
`password` char(40) NOT NULL,
`secret` char(16) DEFAULT NULL,
`type` int NOT NULL DEFAULT '1',
`premium_ends_at` int unsigned NOT NULL DEFAULT '0',
`email` varchar(255) NOT NULL DEFAULT '',
`creation` int NOT NULL DEFAULT '0',
`tibia_coins` int unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `players` (
`id` int NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL,
`group_id` int NOT NULL DEFAULT '1',
`account_id` int NOT NULL DEFAULT '0',
`level` int NOT NULL DEFAULT '1',
`vocation` int NOT NULL DEFAULT '0',
`health` int NOT NULL DEFAULT '150',
`healthmax` int NOT NULL DEFAULT '150',
`experience` bigint unsigned NOT NULL DEFAULT '0',
`lookbody` int NOT NULL DEFAULT '0',
`lookfeet` int NOT NULL DEFAULT '0',
`lookhead` int NOT NULL DEFAULT '0',
`looklegs` int NOT NULL DEFAULT '0',
`looktype` int NOT NULL DEFAULT '136',
`lookaddons` int NOT NULL DEFAULT '0',
`lookmount` int NOT NULL DEFAULT '0',
`lookmounthead` int NOT NULL DEFAULT '0',
`lookmountbody` int NOT NULL DEFAULT '0',
`lookmountlegs` int NOT NULL DEFAULT '0',
`lookmountfeet` int NOT NULL DEFAULT '0',
`direction` tinyint unsigned NOT NULL DEFAULT '2',
`maglevel` int NOT NULL DEFAULT '0',
`mana` int NOT NULL DEFAULT '0',
`manamax` int NOT NULL DEFAULT '0',
`manaspent` bigint unsigned NOT NULL DEFAULT '0',
`soul` int unsigned NOT NULL DEFAULT '0',
`town_id` int NOT NULL DEFAULT '1',
`posx` int NOT NULL DEFAULT '0',
`posy` int NOT NULL DEFAULT '0',
`posz` int NOT NULL DEFAULT '0',
`conditions` blob DEFAULT NULL,
`cap` int NOT NULL DEFAULT '400',
`sex` int NOT NULL DEFAULT '0',
`lastlogin` bigint unsigned NOT NULL DEFAULT '0',
`lastip` int unsigned NOT NULL DEFAULT '0',
`save` tinyint NOT NULL DEFAULT '1',
`skull` tinyint NOT NULL DEFAULT '0',
`skulltime` bigint NOT NULL DEFAULT '0',
`lastlogout` bigint unsigned NOT NULL DEFAULT '0',
`blessings` tinyint NOT NULL DEFAULT '0',
`onlinetime` bigint NOT NULL DEFAULT '0',
`deletion` bigint NOT NULL DEFAULT '0',
`balance` bigint unsigned NOT NULL DEFAULT '0',
`offlinetraining_time` smallint unsigned NOT NULL DEFAULT '43200',
`offlinetraining_skill` int NOT NULL DEFAULT '-1',
`stamina` smallint unsigned NOT NULL DEFAULT '2520',
`skill_fist` int unsigned NOT NULL DEFAULT 10,
`skill_fist_tries` bigint unsigned NOT NULL DEFAULT 0,
`skill_club` int unsigned NOT NULL DEFAULT 10,
`skill_club_tries` bigint unsigned NOT NULL DEFAULT 0,
`skill_sword` int unsigned NOT NULL DEFAULT 10,
`skill_sword_tries` bigint unsigned NOT NULL DEFAULT 0,
`skill_axe` int unsigned NOT NULL DEFAULT 10,
`skill_axe_tries` bigint unsigned NOT NULL DEFAULT 0,
`skill_dist` int unsigned NOT NULL DEFAULT 10,
`skill_dist_tries` bigint unsigned NOT NULL DEFAULT 0,
`skill_shielding` int unsigned NOT NULL DEFAULT 10,
`skill_shielding_tries` bigint unsigned NOT NULL DEFAULT 0,
`skill_fishing` int unsigned NOT NULL DEFAULT 10,
`skill_fishing_tries` bigint unsigned NOT NULL DEFAULT 0,
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`),
FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE,
KEY `vocation` (`vocation`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `account_bans` (
`account_id` int NOT NULL,
`reason` varchar(255) NOT NULL,
`banned_at` bigint NOT NULL,
`expires_at` bigint NOT NULL,
`banned_by` int NOT NULL,
PRIMARY KEY (`account_id`),
FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (`banned_by`) REFERENCES `players` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `account_ban_history` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
`account_id` int NOT NULL,
`reason` varchar(255) NOT NULL,
`banned_at` bigint NOT NULL,
`expired_at` bigint NOT NULL,
`banned_by` int NOT NULL,
PRIMARY KEY (`id`),
FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (`banned_by`) REFERENCES `players` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `account_storage` (
`account_id` int NOT NULL,
`key` int unsigned NOT NULL,
`value` int NOT NULL,
PRIMARY KEY (`account_id`, `key`),
FOREIGN KEY (`account_id`) REFERENCES `accounts`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `ip_bans` (
`ip` int unsigned NOT NULL,
`reason` varchar(255) NOT NULL,
`banned_at` bigint NOT NULL,
`expires_at` bigint NOT NULL,
`banned_by` int NOT NULL,
PRIMARY KEY (`ip`),
FOREIGN KEY (`banned_by`) REFERENCES `players` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_namelocks` (
`player_id` int NOT NULL,
`reason` varchar(255) NOT NULL,
`namelocked_at` bigint NOT NULL,
`namelocked_by` int NOT NULL,
PRIMARY KEY (`player_id`),
FOREIGN KEY (`player_id`) REFERENCES `players` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (`namelocked_by`) REFERENCES `players` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `account_viplist` (
`account_id` int NOT NULL COMMENT 'id of account whose viplist entry it is',
`player_id` int NOT NULL COMMENT 'id of target player of viplist entry',
`description` varchar(128) NOT NULL DEFAULT '',
`icon` tinyint unsigned NOT NULL DEFAULT '0',
`notify` tinyint NOT NULL DEFAULT '0',
UNIQUE KEY `account_player_index` (`account_id`,`player_id`),
FOREIGN KEY (`account_id`) REFERENCES `accounts` (`id`) ON DELETE CASCADE,
FOREIGN KEY (`player_id`) REFERENCES `players` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `guilds` (
`id` int NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL,
`ownerid` int NOT NULL,
`creationdata` int NOT NULL,
`motd` varchar(255) NOT NULL DEFAULT '',
`balance` bigint unsigned NOT NULL DEFAULT '0', -- add war system
`last_execute_points` int NOT NULL DEFAULT '0', -- guild shop system
PRIMARY KEY (`id`),
UNIQUE KEY (`name`),
UNIQUE KEY (`ownerid`),
FOREIGN KEY (`ownerid`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `guild_invites` (
`player_id` int NOT NULL DEFAULT '0',
`guild_id` int NOT NULL DEFAULT '0',
PRIMARY KEY (`player_id`,`guild_id`),
FOREIGN KEY (`player_id`) REFERENCES `players` (`id`) ON DELETE CASCADE,
FOREIGN KEY (`guild_id`) REFERENCES `guilds` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `guild_ranks` (
`id` int NOT NULL AUTO_INCREMENT,
`guild_id` int NOT NULL COMMENT 'guild',
`name` varchar(255) NOT NULL COMMENT 'rank name',
`level` int NOT NULL COMMENT 'rank level - leader, vice, member, maybe something else',
PRIMARY KEY (`id`),
FOREIGN KEY (`guild_id`) REFERENCES `guilds` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `guild_membership` (
`player_id` int NOT NULL,
`guild_id` int NOT NULL,
`rank_id` int NOT NULL,
`nick` varchar(15) NOT NULL DEFAULT '',
PRIMARY KEY (`player_id`),
FOREIGN KEY (`player_id`) REFERENCES `players` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (`guild_id`) REFERENCES `guilds` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
FOREIGN KEY (`rank_id`) REFERENCES `guild_ranks` (`id`) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `guild_wars` (
`id` int NOT NULL AUTO_INCREMENT,
`guild1` int NOT NULL DEFAULT '0',
`guild2` int NOT NULL DEFAULT '0',
`name1` varchar(255) NOT NULL,
`name2` varchar(255) NOT NULL,
`status` tinyint NOT NULL DEFAULT '0',
`started` bigint NOT NULL DEFAULT '0',
`ended` bigint NOT NULL DEFAULT '0',
`frags` int NOT NULL DEFAULT '0', -- add war system
`payment` bigint unsigned NOT NULL DEFAULT '0', -- add war system
PRIMARY KEY (`id`),
KEY `guild1` (`guild1`),
KEY `guild2` (`guild2`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `guildwar_kills` (
`id` int NOT NULL AUTO_INCREMENT,
`killer` varchar(50) NOT NULL,
`target` varchar(50) NOT NULL,
`killerguild` int NOT NULL DEFAULT '0',
`targetguild` int NOT NULL DEFAULT '0',
`warid` int NOT NULL DEFAULT '0',
`time` bigint NOT NULL,
PRIMARY KEY (`id`),
FOREIGN KEY (`warid`) REFERENCES `guild_wars` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `houses` (
`id` int NOT NULL AUTO_INCREMENT,
`owner` int NOT NULL,
`paid` int unsigned NOT NULL DEFAULT '0',
`warnings` int NOT NULL DEFAULT '0',
`name` varchar(255) NOT NULL,
`rent` int NOT NULL DEFAULT '0',
`town_id` int NOT NULL DEFAULT '0',
`bid` int NOT NULL DEFAULT '0',
`bid_end` int NOT NULL DEFAULT '0',
`last_bid` int NOT NULL DEFAULT '0',
`highest_bidder` int NOT NULL DEFAULT '0',
`size` int NOT NULL DEFAULT '0',
`beds` int NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
KEY `owner` (`owner`),
KEY `town_id` (`town_id`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `house_lists` (
`house_id` int NOT NULL,
`listid` int NOT NULL,
`list` text NOT NULL,
FOREIGN KEY (`house_id`) REFERENCES `houses` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `market_history` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
`player_id` int NOT NULL,
`sale` tinyint NOT NULL DEFAULT '0',
`itemtype` smallint unsigned NOT NULL,
`amount` smallint unsigned NOT NULL,
`price` int unsigned NOT NULL DEFAULT '0',
`expires_at` bigint unsigned NOT NULL,
`inserted` bigint unsigned NOT NULL,
`state` tinyint unsigned NOT NULL,
PRIMARY KEY (`id`),
KEY `player_id` (`player_id`, `sale`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `market_offers` (
`id` int unsigned NOT NULL AUTO_INCREMENT,
`player_id` int NOT NULL,
`sale` tinyint NOT NULL DEFAULT '0',
`itemtype` smallint unsigned NOT NULL,
`amount` smallint unsigned NOT NULL,
`created` bigint unsigned NOT NULL,
`anonymous` tinyint NOT NULL DEFAULT '0',
`price` int unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
KEY `sale` (`sale`,`itemtype`),
KEY `created` (`created`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `players_online` (
`player_id` int NOT NULL,
PRIMARY KEY (`player_id`)
) ENGINE=MEMORY DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_deaths` (
`player_id` int NOT NULL,
`time` bigint unsigned NOT NULL DEFAULT '0',
`level` int NOT NULL DEFAULT '1',
`killed_by` varchar(255) NOT NULL,
`is_player` tinyint NOT NULL DEFAULT '1',
`mostdamage_by` varchar(100) NOT NULL,
`mostdamage_is_player` tinyint NOT NULL DEFAULT '0',
`unjustified` tinyint NOT NULL DEFAULT '0',
`mostdamage_unjustified` tinyint NOT NULL DEFAULT '0',
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE,
KEY `killed_by` (`killed_by`),
KEY `mostdamage_by` (`mostdamage_by`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_inboxitems` (
`player_id` int NOT NULL,
`sid` int NOT NULL,
`pid` int NOT NULL DEFAULT '0',
`itemtype` smallint unsigned NOT NULL,
`count` smallint NOT NULL DEFAULT '0',
`attributes` blob NOT NULL,
UNIQUE KEY `player_id_2` (`player_id`, `sid`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_storeinboxitems` (
`player_id` int NOT NULL,
`sid` int NOT NULL,
`pid` int NOT NULL DEFAULT '0',
`itemtype` smallint unsigned NOT NULL,
`count` smallint NOT NULL DEFAULT '0',
`attributes` blob NOT NULL,
UNIQUE KEY `player_id_2` (`player_id`, `sid`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_depotlockeritems` (
`player_id` int NOT NULL,
`sid` int NOT NULL COMMENT 'any given range eg 0-100 will be reserved for depot lockers and all > 100 will be then normal items inside depots',
`pid` int NOT NULL DEFAULT '0',
`itemtype` smallint NOT NULL,
`count` smallint NOT NULL DEFAULT '0',
`attributes` blob NOT NULL,
UNIQUE KEY `player_id_2` (`player_id`, `sid`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_depotitems` (
`player_id` int NOT NULL,
`sid` int NOT NULL COMMENT 'any given range eg 0-100 will be reserved for depot lockers and all > 100 will be then normal items inside depots',
`pid` int NOT NULL DEFAULT '0',
`itemtype` smallint unsigned NOT NULL,
`count` smallint NOT NULL DEFAULT '0',
`attributes` blob NOT NULL,
UNIQUE KEY `player_id_2` (`player_id`, `sid`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_items` (
`player_id` int NOT NULL DEFAULT '0',
`pid` int NOT NULL DEFAULT '0',
`sid` int NOT NULL DEFAULT '0',
`itemtype` smallint unsigned NOT NULL,
`count` smallint NOT NULL DEFAULT '0',
`attributes` blob NOT NULL,
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE,
KEY `sid` (`sid`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_spells` (
`player_id` int NOT NULL,
`name` varchar(255) NOT NULL,
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_storage` (
`player_id` int NOT NULL DEFAULT '0',
`key` int unsigned NOT NULL DEFAULT '0',
`value` int NOT NULL DEFAULT '0',
PRIMARY KEY (`player_id`,`key`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `player_outfits` (
`player_id` int NOT NULL DEFAULT '0',
`outfit_id` smallint unsigned NOT NULL DEFAULT '0',
`addons` tinyint unsigned NOT NULL DEFAULT '0',
PRIMARY KEY (`player_id`,`outfit_id`),
FOREIGN KEY (`player_id`) REFERENCES `players`(`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `server_config` (
`config` varchar(50) NOT NULL,
`value` varchar(256) NOT NULL DEFAULT '',
PRIMARY KEY `config` (`config`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `tile_store` (
`house_id` int NOT NULL,
`data` longblob NOT NULL,
FOREIGN KEY (`house_id`) REFERENCES `houses` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
CREATE TABLE IF NOT EXISTS `towns` (
`id` int NOT NULL AUTO_INCREMENT,
`name` varchar(255) NOT NULL,
`posx` int NOT NULL DEFAULT '0',
`posy` int NOT NULL DEFAULT '0',
`posz` int NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
UNIQUE KEY `name` (`name`)
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;
INSERT INTO `server_config` (`config`, `value`) VALUES ('db_version', '30'), ('motd_hash', ''), ('motd_num', '0'), ('players_record', '0');
DROP TRIGGER IF EXISTS `ondelete_players`;
DROP TRIGGER IF EXISTS `oncreate_guilds`;
DELIMITER //
CREATE TRIGGER `ondelete_players` BEFORE DELETE ON `players`
FOR EACH ROW BEGIN
UPDATE `houses` SET `owner` = 0 WHERE `owner` = OLD.`id`;
END
//
CREATE TRIGGER `oncreate_guilds` AFTER INSERT ON `guilds`
FOR EACH ROW BEGIN
INSERT INTO `guild_ranks` (`name`, `level`, `guild_id`) VALUES ('the Leader', 3, NEW.`id`);
INSERT INTO `guild_ranks` (`name`, `level`, `guild_id`) VALUES ('a Vice-Leader', 2, NEW.`id`);
INSERT INTO `guild_ranks` (`name`, `level`, `guild_id`) VALUES ('a Member', 1, NEW.`id`);
END
//
DELIMITER ;
-- lottery system
CREATE TABLE IF NOT EXISTS `lottery` (
`id` int NOT NULL AUTO_INCREMENT,
`player_id` int NOT NULL,
`item_id` smallint unsigned NOT NULL,
`item_count` smallint unsigned NOT NULL DEFAULT '1',
`item_name` varchar(255) NOT NULL,
`addData` int NOT NULL DEFAULT '0',
PRIMARY KEY (`id`),
FOREIGN KEY (`player_id`) REFERENCES `players` (`id`) ON DELETE CASCADE
) ENGINE=InnoDB DEFAULT CHARACTER SET=utf8;