Removed NioTSO client and server

- NioTSO client isn't needed because we're using RayLib
- Added FreeSO's API server to handle most backend operations
This commit is contained in:
Tony Bark 2024-05-01 02:55:43 -04:00
parent f12ba1502b
commit 22191ce648
591 changed files with 53264 additions and 3362 deletions

View file

@ -0,0 +1,6 @@
CREATE TRIGGER `fso_avatars_BEFORE_INSERT` BEFORE INSERT ON `fso_avatars` FOR EACH ROW BEGIN
IF (SELECT COUNT(*) FROM fso_avatars a WHERE NEW.user_id = a.user_id) >= 3 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Cannot own more than 3 avatars.';
END IF;
END

View file

@ -0,0 +1,13 @@
CREATE TRIGGER `fso_avatars_BEFORE_UPDATE` BEFORE UPDATE ON `fso_avatars` FOR EACH ROW BEGIN
IF NEW.budget<0 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Transaction would cause avatar to have negative budget.';
END IF;
END;
CREATE TRIGGER `fso_objects_BEFORE_UPDATE` BEFORE UPDATE ON `fso_objects` FOR EACH ROW BEGIN
IF NEW.budget<0 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Transaction would cause object to have negative budget.';
END IF;
END;

View file

@ -0,0 +1,10 @@
CREATE TRIGGER `fso_roommates_BEFORE_INSERT` BEFORE INSERT ON `fso_roommates` FOR EACH ROW BEGIN
IF (SELECT COUNT(*) FROM fso_roommates a WHERE NEW.avatar_id = a.avatar_id) > 0 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Cannot be a roommate of more than one lot. (currently, will likely change in future.)';
END IF;
IF (SELECT COUNT(*) FROM fso_roommates a WHERE NEW.lot_id = a.lot_id) >= 8 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Cannot have more than 8 roommates in a lot.';
END IF;
END;

View file

@ -0,0 +1,11 @@
CREATE TABLE IF NOT EXISTS `fso_bookmarks` (
`avatar_id` int(10) unsigned NOT NULL,
`type` tinyint(3) unsigned NOT NULL,
`target_id` int(10) unsigned NOT NULL,
PRIMARY KEY (`avatar_id`,`type`,`target_id`),
KEY `FK_fso_bookmarks_fso_avatars_target` (`target_id`),
CONSTRAINT `FK_fso_bookmarks_fso_avatars_src` FOREIGN KEY (`avatar_id`) REFERENCES `fso_avatars` (`avatar_id`),
CONSTRAINT `FK_fso_bookmarks_fso_avatars_target` FOREIGN KEY (`target_id`) REFERENCES `fso_avatars` (`avatar_id`)
)
COLLATE='utf8_general_ci'
ENGINE=InnoDB;

View file

@ -0,0 +1,3 @@
ALTER TABLE `fso_lot_admit`
DROP PRIMARY KEY,
ADD PRIMARY KEY (`avatar_id`, `lot_id`, `admit_type`);

View file

@ -0,0 +1,47 @@
CREATE TABLE IF NOT EXISTS `fso_outfits` (
`outfit_id` int(11) NOT NULL AUTO_INCREMENT,
`avatar_owner` int(10) unsigned DEFAULT NULL,
`object_owner` int(11) unsigned DEFAULT NULL,
`asset_id` bigint(20) unsigned DEFAULT NULL,
`sale_price` int(11) NOT NULL,
`purchase_price` int(11) NOT NULL,
`outfit_type` tinyint(3) unsigned NOT NULL DEFAULT '0' COMMENT 'See VMPersonSuits',
`outfit_source` enum('cas','rack') NOT NULL DEFAULT 'cas',
PRIMARY KEY (`outfit_id`),
KEY `FK_fso_outfits_fso_avatars` (`avatar_owner`),
KEY `FK_fso_outfits_fso_objects` (`object_owner`),
CONSTRAINT `FK_fso_outfits_fso_avatars` FOREIGN KEY (`avatar_owner`) REFERENCES `fso_avatars` (`avatar_id`) ON DELETE CASCADE,
CONSTRAINT `FK_fso_outfits_fso_objects` FOREIGN KEY (`object_owner`) REFERENCES `fso_objects` (`object_id`) ON DELETE CASCADE
)
COLLATE='utf8_general_ci'
ENGINE=InnoDB;
CREATE TRIGGER `fso_outfits_before_insert` BEFORE INSERT ON `fso_outfits` FOR EACH ROW BEGIN
IF NEW.object_owner IS NOT NULL THEN
IF (SELECT COUNT(*) FROM fso_outfits o WHERE NEW.object_owner = o.object_owner) >= 20 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Cannot have more than 20 outfits in a rack.';
END IF;
END IF;
END;
CREATE TRIGGER `fso_outfits_before_update` BEFORE UPDATE ON `fso_outfits` FOR EACH ROW BEGIN
IF NEW.avatar_owner IS NOT NULL THEN
IF (SELECT COUNT(*) FROM fso_outfits o WHERE NEW.avatar_owner = o.avatar_owner AND o.outfit_type = NEW.outfit_type) >= 5 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Cannot have more than 5 outfits per category in backpack.';
END IF;
END IF;
END;
-- Migrate existing daywear --
INSERT INTO fso_outfits (avatar_owner, asset_id, sale_price, purchase_price, outfit_type, outfit_source)
SELECT avatar_id, body, 0, 0, 0, 'cas' FROM fso_avatars;
-- Give everyone default sleepswear --
INSERT INTO fso_outfits (avatar_owner, asset_id, sale_price, purchase_price, outfit_type, outfit_source)
SELECT avatar_id, if(gender = 'male', CAST(0x5440000000D as UNSIGNED), CAST(0x5150000000D as UNSIGNED)), 0, 0, 5, 'cas' FROM fso_avatars;
-- Give everyone default swimwear --
INSERT INTO fso_outfits (avatar_owner, asset_id, sale_price, purchase_price, outfit_type, outfit_source)
SELECT avatar_id, if(gender = 'male', CAST(0x5470000000D as UNSIGNED), CAST(0x620000000D as UNSIGNED)), 0, 0, 2, 'cas' FROM fso_avatars;

View file

@ -0,0 +1,41 @@
CREATE TABLE IF NOT EXISTS `fso_lot_visits` (
`lot_visit_id` int(11) unsigned NOT NULL AUTO_INCREMENT,
`avatar_id` int(11) unsigned NOT NULL,
`lot_id` int(11) NOT NULL,
`type` enum('owner','roommate','visitor') DEFAULT NULL,
`status` enum('active','closed','failed') NOT NULL,
`time_created` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP,
`time_closed` datetime DEFAULT NULL,
PRIMARY KEY (`lot_visit_id`),
KEY `FK_fso_avatar_audits_fso_avatars` (`avatar_id`),
KEY `FK_fso_lot_visitors_fso_lots` (`lot_id`),
CONSTRAINT `FK_fso_avatar_audits_fso_avatars` FOREIGN KEY (`avatar_id`) REFERENCES `fso_avatars` (`avatar_id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `FK_fso_lot_visitors_fso_lots` FOREIGN KEY (`lot_id`) REFERENCES `fso_lots` (`lot_id`) ON DELETE CASCADE ON UPDATE CASCADE
)
COLLATE='utf8_general_ci'
ENGINE=InnoDB;
CREATE FUNCTION `fso_lot_visits_create`(`p_avatar_id` INT, `p_lot_id` INT, `p_visitor_type` VARCHAR(50)) RETURNS int(11)
READS SQL DATA
BEGIN
#Error any open active visit, can only have one active
UPDATE fso_lot_visits SET `status` = 'failed', time_closed = current_timestamp WHERE avatar_id = p_avatar_id AND `status` = 'active';
#Record visit
INSERT INTO fso_lot_visits (avatar_id, lot_id, type, status) VALUES (p_avatar_id, p_lot_id, p_visitor_type, 'active');
RETURN LAST_INSERT_ID();
END;
CREATE TABLE IF NOT EXISTS `fso_lot_top_100` (
`category` enum('none','welcome','money','skills','services','entertainment','romance','shopping','games','offbeat','residence') NOT NULL,
`rank` tinyint(4) unsigned NOT NULL,
`shard_id` int(11) NOT NULL,
`lot_id` int(11) DEFAULT NULL,
`minutes` int(11) DEFAULT NULL,
`date` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`category`,`rank`,`shard_id`),
KEY `FK_fso_lots_top_100_fso_shards` (`shard_id`),
KEY `FK_fso_lots_top_100_fso_lots` (`lot_id`),
CONSTRAINT `FK_fso_lots_top_100_fso_lots` FOREIGN KEY (`lot_id`) REFERENCES `fso_lots` (`lot_id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `FK_fso_lots_top_100_fso_shards` FOREIGN KEY (`shard_id`) REFERENCES `fso_shards` (`shard_id`)
) COLLATE='utf8_general_ci'
ENGINE=InnoDB;

View file

@ -0,0 +1,13 @@
CREATE TABLE IF NOT EXISTS `fso_hosts` (
`call_sign` varchar(50) NOT NULL,
`role` enum('city','lot','task') NOT NULL,
`status` enum('up','down') NOT NULL,
`internal_host` varchar(100) NOT NULL,
`public_host` varchar(100) NOT NULL,
`time_boot` datetime NOT NULL,
`shard_id` int(11) DEFAULT NULL,
PRIMARY KEY (`call_sign`),
KEY `FK_fso_hosts_fso_shards` (`shard_id`),
CONSTRAINT `FK_fso_hosts_fso_shards` FOREIGN KEY (`shard_id`) REFERENCES `fso_shards` (`shard_id`) ON DELETE CASCADE ON UPDATE CASCADE
) COLLATE='utf8_general_ci'
ENGINE=InnoDB;

View file

@ -0,0 +1,12 @@
CREATE TABLE IF NOT EXISTS `fso_tasks` (
`task_id` int(11) NOT NULL AUTO_INCREMENT,
`task_type` enum('prune_database','bonus') NOT NULL,
`task_status` enum('in_progress','completed','failed') NOT NULL,
`time_created` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP,
`time_completed` datetime DEFAULT NULL,
`shard_id` int(11) DEFAULT NULL,
PRIMARY KEY (`task_id`),
KEY `FK_fso_tasks_fso_shards` (`shard_id`),
CONSTRAINT `FK_fso_tasks_fso_shards` FOREIGN KEY (`shard_id`) REFERENCES `fso_shards` (`shard_id`) ON DELETE CASCADE ON UPDATE CASCADE
) COLLATE='utf8_general_ci'
ENGINE=InnoDB;

View file

@ -0,0 +1,65 @@
CREATE TABLE IF NOT EXISTS `fso_lot_visit_totals` (
`lot_id` int(11) NOT NULL,
`date` date NOT NULL,
`minutes` int(11) NOT NULL,
PRIMARY KEY (`lot_id`,`date`),
CONSTRAINT `FK_fso_lot_visit_totals_fso_lots` FOREIGN KEY (`lot_id`) REFERENCES `fso_lots` (`lot_id`) ON DELETE CASCADE ON UPDATE CASCADE
) COLLATE='utf8_general_ci'
ENGINE=InnoDB;
CREATE PROCEDURE `fso_lot_top_100_calc_category`(IN `p_category` VARCHAR(50), IN `p_date` DATE, IN `p_shard_id` INT)
SQL SECURITY INVOKER
BEGIN
DECLARE EXIT HANDLER FOR SQLEXCEPTION
BEGIN
ROLLBACK;
END;
SET @date = p_date;
SET @start_date = DATE_SUB(@date, INTERVAL 4 DAY);
SET @timestamp = current_timestamp;
SET @row_number = 0;
START TRANSACTION;
# Remove old
DELETE FROM fso_lot_top_100 WHERE shard_id = p_shard_id AND category = p_category;
# Insert new
INSERT INTO fso_lot_top_100 (category, rank, shard_id, lot_id, minutes, date)
SELECT category,
(@row_number:=@row_number + 1) AS rank,
shard_id,
lot_id,
minutes,
date
FROM (
SELECT lot.category, lot.lot_id, lot.shard_id, FLOOR(AVG(visits.minutes)) as minutes, @timestamp as date
FROM fso_lot_visit_totals visits
INNER JOIN fso_lots lot ON visits.lot_id = lot.lot_id
WHERE lot.category = p_category
AND date BETWEEN @start_date AND @date
AND lot.shard_id = p_shard_id
GROUP BY lot_id
ORDER BY minutes DESC
LIMIT 100
) as top100;
COMMIT;
END;
CREATE PROCEDURE `fso_lot_top_100_calc_all`(IN `p_date` DATE, IN `p_shard_id` INT)
SQL SECURITY INVOKER
BEGIN
CALL fso_lot_top_100_calc_category('money', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('offbeat', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('romance', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('services', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('shopping', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('skills', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('welcome', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('games', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('entertainment', p_date, p_shard_id);
CALL fso_lot_top_100_calc_category('residence', p_date, p_shard_id);
END;

View file

@ -0,0 +1,14 @@
CREATE TABLE IF NOT EXISTS `fso_bonus` (
`avatar_id` int(10) unsigned NOT NULL DEFAULT '0',
`period` date NOT NULL,
`bonus_visitor` int(11) DEFAULT NULL,
`bonus_property` int(11) DEFAULT NULL,
`bonus_sim` int(11) DEFAULT NULL,
PRIMARY KEY (`avatar_id`,`period`),
CONSTRAINT `FK_fso_bonus_fso_avatars` FOREIGN KEY (`avatar_id`) REFERENCES `fso_avatars` (`avatar_id`) ON DELETE CASCADE ON UPDATE CASCADE
) COLLATE='utf8_general_ci'
ENGINE=InnoDB;
CREATE TRIGGER `fso_bonus_after_insert` AFTER INSERT ON `fso_bonus` FOR EACH ROW BEGIN
UPDATE fso_avatars a SET budget = (budget + IFNULL(NEW.bonus_visitor,0) + IFNULL(NEW.bonus_property,0) + IFNULL(NEW.bonus_sim,0)) WHERE a.avatar_id = NEW.avatar_id;
END;

View file

@ -0,0 +1,11 @@
CREATE TABLE IF NOT EXISTS `fso_ip_ban` (
`user_id` INT UNSIGNED NOT NULL,
`ip_address` VARCHAR(100) NULL,
`banreason` VARCHAR(500) NULL,
`end_date` INT(10) NOT NULL DEFAULT 0,
PRIMARY KEY (`user_id`),
CONSTRAINT `fso_ban_user`
FOREIGN KEY (`user_id`)
REFERENCES `fso_users` (`user_id`)
ON DELETE CASCADE
ON UPDATE CASCADE);

View file

@ -0,0 +1,6 @@

ALTER TABLE `fso_shards`
ADD `version_name` varchar(100) NOT NULL DEFAULT 'unknown';
ALTER TABLE `fso_shards`
ADD `version_number` varchar(100) NOT NULL DEFAULT '0';

View file

@ -0,0 +1,5 @@
ALTER TABLE `fso_users`
ADD COLUMN `client_id` VARCHAR(100) NOT NULL DEFAULT 0 AFTER `last_ip`;
ALTER TABLE `fso_ip_ban`
ADD COLUMN `client_id` VARCHAR(100) NOT NULL DEFAULT '0' AFTER `end_date`;

View file

@ -0,0 +1,34 @@
-- claims
ALTER TABLE `fso_avatar_claims`
DROP FOREIGN KEY `FK_fso_avatar_claims_fso_avatars`;
ALTER TABLE `fso_avatar_claims`
ADD CONSTRAINT `FK_fso_avatar_claims_fso_avatars`
FOREIGN KEY (`avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE;
-- bookmarks
ALTER TABLE `fso_bookmarks`
DROP FOREIGN KEY `FK_fso_bookmarks_fso_avatars_src`,
DROP FOREIGN KEY `FK_fso_bookmarks_fso_avatars_target`;
ALTER TABLE `fso_bookmarks`
ADD CONSTRAINT `FK_fso_bookmarks_fso_avatars_src`
FOREIGN KEY (`avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
ADD CONSTRAINT `FK_fso_bookmarks_fso_avatars_target`
FOREIGN KEY (`target_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE;
-- lot owners - now nullable. null owner lots are deleted.
ALTER TABLE `fso_lots`
CHANGE COLUMN `owner_id` `owner_id` INT(10) UNSIGNED NULL ;

View file

@ -0,0 +1,2 @@
ALTER TABLE `fso_tasks`
CHANGE COLUMN `task_type` `task_type` ENUM('prune_database', 'bonus', 'shutdown', 'job_balance', 'multi_check', 'prune_abandoned_lots') NOT NULL ;

View file

@ -0,0 +1,50 @@
CREATE TABLE `fso_inbox` (
`message_id` INT NOT NULL AUTO_INCREMENT,
`sender_id` INT UNSIGNED NOT NULL,
`target_id` INT UNSIGNED NOT NULL,
`subject` VARCHAR(128) NOT NULL,
`body` VARCHAR(1500) NOT NULL,
`sender_name` VARCHAR(64) NOT NULL,
`time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
`msg_type` INT NOT NULL DEFAULT 0,
`msg_subtype` INT NOT NULL DEFAULT 0,
`read_state` INT NOT NULL DEFAULT 0,
`reply_id` INT NULL DEFAULT NULL,
PRIMARY KEY (`message_id`),
INDEX `index_target_inbox` (`target_id` ASC),
CONSTRAINT `fso_target_avatar`
FOREIGN KEY (`target_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE);
CREATE TABLE `fso_events` (
`event_id` INT NOT NULL AUTO_INCREMENT,
`title` VARCHAR(128) NULL,
`description` VARCHAR(500) NULL,
`start_day` DATETIME NOT NULL,
`end_day` DATETIME NOT NULL,
`type` ENUM('mail_only', 'free_object', 'free_money', 'free_green', 'obj_tuning') NOT NULL,
`value` INT NOT NULL,
`value2` INT NOT NULL DEFAULT 0,
`mail_subject` VARCHAR(128) NULL,
`mail_message` VARCHAR(1000) NULL,
`mail_sender` INT NULL,
`mail_sender_name` VARCHAR(64) NULL,
PRIMARY KEY (`event_id`));
CREATE TABLE `fso_event_participation` (
`event_id` INT NOT NULL,
`user_id` INT UNSIGNED NOT NULL,
PRIMARY KEY (`event_id`, `user_id`),
INDEX `fso_event_part_user_idx` (`user_id` ASC),
CONSTRAINT `fso_event_part_id`
FOREIGN KEY (`event_id`)
REFERENCES `fso_events` (`event_id`)
ON DELETE CASCADE
ON UPDATE NO ACTION,
CONSTRAINT `fso_event_part_user`
FOREIGN KEY (`user_id`)
REFERENCES `fso_users` (`user_id`)
ON DELETE CASCADE
ON UPDATE CASCADE);

View file

@ -0,0 +1,25 @@
ALTER TABLE `fso_transactions`
DROP COLUMN `time_last`,
CHANGE COLUMN `time_first` `day` INT(11) UNSIGNED NOT NULL AFTER `transaction_type`,
CHANGE COLUMN `value_per_hour` `value_per_hour` DOUBLE UNSIGNED NULL ,
DROP PRIMARY KEY,
ADD PRIMARY KEY (`from_id`, `to_id`, `transaction_type`, `day`),
ADD INDEX `fso_transaction_from` (`from_id` ASC),
ADD INDEX `fso_transaction_to` (`to_id` ASC),
ADD INDEX `fso_transaction_type` (`transaction_type` ASC);
CREATE TABLE `fso_tuning` (
`tuning_type` VARCHAR(128) NOT NULL,
`tuning_table` INT NOT NULL,
`tuning_index` INT NOT NULL,
`value` FLOAT NOT NULL,
`owner_type` ENUM('STATIC', 'DYNAMIC', 'EVENT') NOT NULL DEFAULT 'STATIC',
`owner_id` INT NULL DEFAULT NULL,
INDEX `tuning_by_owner` (`owner_type` ASC, `owner_id` ASC));
CREATE TABLE `fso_dyn_payouts` (
`day` INT NOT NULL,
`skilltype` INT NOT NULL,
`multiplier` FLOAT NOT NULL DEFAULT 1,
`flags` INT NOT NULL DEFAULT 0,
PRIMARY KEY (`day`, `skilltype`));

View file

@ -0,0 +1,4 @@
ALTER TABLE `fso_lots`
ADD COLUMN `skill_mode` TINYINT UNSIGNED NOT NULL DEFAULT '0' AFTER `move_flags`;
UPDATE fso_lots SET skill_mode = 1 where category IN ("services", "entertainment", "romance");

View file

@ -0,0 +1,10 @@
CREATE TABLE `fso_email_confirm` (
`type` ENUM('email','password') NOT NULL DEFAULT 'email',
`email` VARCHAR(50) NULL DEFAULT NULL,
`token` VARCHAR(50) NULL DEFAULT NULL,
`expires` INT(11) NULL DEFAULT NULL
)
COMMENT='Table to control necessary email confirmation for registration or password reset.'
COLLATE='latin1_swedish_ci'
ENGINE=InnoDB
;

View file

@ -0,0 +1,3 @@
ALTER TABLE `fso_lots`
ADD COLUMN `thumb3d_dirty` TINYINT(3) UNSIGNED NOT NULL DEFAULT 0 AFTER `skill_mode`,
ADD COLUMN `thumb3d_time` INT(10) UNSIGNED NOT NULL DEFAULT 0 AFTER `thumb3d_dirty`;

View file

@ -0,0 +1,2 @@
ALTER TABLE `fso_users`
ADD COLUMN `last_login` INT(10) UNSIGNED NOT NULL DEFAULT 0 AFTER `client_id`;

View file

@ -0,0 +1,260 @@
CREATE TABLE `fso_election_cycles` (
`cycle_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`start_date` INT(10) UNSIGNED NOT NULL,
`end_date` INT(10) UNSIGNED NOT NULL,
`current_state` ENUM('shutdown', 'nomination', 'election', 'ended') NOT NULL,
`election_type` ENUM('election', 'shutdown') NOT NULL,
PRIMARY KEY (`cycle_id`));
CREATE TABLE `fso_neighborhoods` (
`neighborhood_id` INT NOT NULL AUTO_INCREMENT,
`name` VARCHAR(100) NOT NULL,
`description` VARCHAR(1000) NOT NULL DEFAULT '',
`shard_id` INT(11) NOT NULL,
`location` INT(10) ZEROFILL UNSIGNED NOT NULL,
`color` INT UNSIGNED NOT NULL DEFAULT 0xffffffff,
`flag` INT UNSIGNED NOT NULL DEFAULT 0,
`town_hall_id` INT(11) NULL,
`icon_url` VARCHAR(100) NULL,
`guid` VARCHAR(45) NOT NULL,
`mayor_id` INT(10) UNSIGNED NULL,
`mayor_elected_date` INT(10) UNSIGNED NOT NULL DEFAULT 0,
`election_cycle_id` INT(10) UNSIGNED NULL,
PRIMARY KEY (`neighborhood_id`),
UNIQUE INDEX `town_hall_id_UNIQUE` (`town_hall_id` ASC),
UNIQUE INDEX `guid_UNIQUE` (`guid` ASC),
UNIQUE INDEX `mayor_id_UNIQUE` (`mayor_id` ASC),
INDEX `fso_neigh_cycle_idx` (`election_cycle_id` ASC),
INDEX `fso_neigh_shard_idx` (`shard_id` ASC),
CONSTRAINT `fso_neigh_town_hall`
FOREIGN KEY (`town_hall_id`)
REFERENCES `fso_lots` (`lot_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_neigh_mayor`
FOREIGN KEY (`mayor_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_neigh_cycle`
FOREIGN KEY (`election_cycle_id`)
REFERENCES `fso_election_cycles` (`cycle_id`)
ON DELETE RESTRICT
ON UPDATE CASCADE,
CONSTRAINT `fso_neigh_shard`
FOREIGN KEY (`shard_id`)
REFERENCES `fso_shards` (`shard_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Neighborhoods within each shard. Typically created ingame and then imported using `server import_nhood <shard_id> <file>`.';
CREATE TABLE `fso_election_votes` (
`election_cycle_id` INT(10) UNSIGNED NOT NULL,
`from_avatar_id` INT(10) UNSIGNED NOT NULL,
`type` ENUM('vote', 'nomination') NOT NULL,
`target_avatar_id` INT(10) UNSIGNED NOT NULL,
`date` INT(10) UNSIGNED NOT NULL,
PRIMARY KEY (`election_cycle_id`, `from_avatar_id`, `type`),
INDEX `fso_vote_from_idx` (`from_avatar_id` ASC),
INDEX `fso_vote_to_idx` (`target_avatar_id` ASC),
CONSTRAINT `fso_evote_cycle`
FOREIGN KEY (`election_cycle_id`)
REFERENCES `fso_election_cycles` (`cycle_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_evote_from`
FOREIGN KEY (`from_avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_evote_to`
FOREIGN KEY (`target_avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Votes and Nominations for mayor election cycles. You can get the neighborhood id from the election cycle.';
CREATE TABLE `fso_election_candidates` (
`election_cycle_id` INT UNSIGNED NOT NULL,
`candidate_avatar_id` INT UNSIGNED NOT NULL,
`comment` VARCHAR(200) NULL DEFAULT 'No comment.',
`disqualified` TINYINT UNSIGNED NOT NULL DEFAULT 0 COMMENT 'Boolean. True if this mayor has been disqualified for some reason.',
PRIMARY KEY (`election_cycle_id`, `candidate_avatar_id`),
INDEX `fso_candidate_avatar_idx` (`candidate_avatar_id` ASC),
CONSTRAINT `fso_candidate_cycle`
FOREIGN KEY (`election_cycle_id`)
REFERENCES `fso_election_cycles` (`cycle_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_candidate_avatar`
FOREIGN KEY (`candidate_avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Candidates for an election cycle. You can get the neighborhood id from the election cycle.';
CREATE TABLE `fso_mayor_ratings` (
`rating_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`from_user_id` INT UNSIGNED NOT NULL,
`to_user_id` INT UNSIGNED NOT NULL,
`rating` INT UNSIGNED NOT NULL DEFAULT 0,
`comment` VARCHAR(200) NOT NULL DEFAULT 'No Comment.',
`date` INT UNSIGNED NOT NULL DEFAULT 0,
`from_avatar_id` INT UNSIGNED NULL,
`to_avatar_id` INT UNSIGNED NULL,
`anonymous` TINYINT UNSIGNED NOT NULL DEFAULT 1,
PRIMARY KEY (`rating_id`),
INDEX `fso_mrating_to_idx` (`to_user_id` ASC),
INDEX `fso_mrating_from_idx` (`from_user_id` ASC),
INDEX `fso_mrating_froma_idx` (`from_avatar_id` ASC),
INDEX `fso_mrating_toa_idx` (`to_avatar_id` ASC),
CONSTRAINT `fso_mrating_from`
FOREIGN KEY (`from_user_id`)
REFERENCES `fso_users` (`user_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_mrating_to`
FOREIGN KEY (`to_user_id`)
REFERENCES `fso_users` (`user_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_mrating_froma`
FOREIGN KEY (`from_avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE SET NULL
ON UPDATE CASCADE,
CONSTRAINT `fso_mrating_toa`
FOREIGN KEY (`to_avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE SET NULL
ON UPDATE CASCADE)
COMMENT = 'User ID is used for ratings so people can\'t dodge their reviews by using another avatar or creating another account. Avatar IDs are still stored for possible visual reference, though the visual reference can be nulled if the avatar is deleted.';
CREATE TABLE `fso_bulletin_posts` (
`bulletin_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`neighborhood_id` INT NOT NULL,
`avatar_id` INT UNSIGNED NOT NULL,
`title` VARCHAR(64) NOT NULL,
`body` VARCHAR(1000) NOT NULL,
`date` INT UNSIGNED NOT NULL,
`flags` INT UNSIGNED NOT NULL DEFAULT 0,
PRIMARY KEY (`bulletin_id`),
INDEX `fso_bulletin_neigh_idx` (`neighborhood_id` ASC),
INDEX `fso_bulletin_poster_idx` (`avatar_id` ASC),
CONSTRAINT `fso_bulletin_neigh`
FOREIGN KEY (`neighborhood_id`)
REFERENCES `fso_neighborhoods` (`neighborhood_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_bulletin_poster`
FOREIGN KEY (`avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Posts for neighborhood bulletin boards. Can only be made by avatars that live in that neighborhood.';
ALTER TABLE `fso_avatars`
ADD COLUMN `custom_guid` INT UNSIGNED NULL AFTER `moderation_level`,
ADD COLUMN `move_date` INT UNSIGNED NOT NULL DEFAULT '0' AFTER `custom_guid`,
ADD COLUMN `name_date` INT UNSIGNED NOT NULL DEFAULT '0' AFTER `move_date`,
ADD COLUMN `mayor_nhood` INT NULL AFTER `name_date`,
ADD INDEX `FK_avatar_mayor_idx` (`mayor_nhood` ASC);
ALTER TABLE `fso_avatars`
ADD CONSTRAINT `FK_avatar_mayor`
FOREIGN KEY (`mayor_nhood`)
REFERENCES `fso_neighborhoods` (`neighborhood_id`)
ON DELETE SET NULL
ON UPDATE CASCADE;
ALTER TABLE `fso_mayor_ratings`
ADD COLUMN `neighborhood` INT(10) UNSIGNED NOT NULL AFTER `anonymous`;
ALTER TABLE `fso_lots`
CHANGE COLUMN `category` `category` ENUM('none', 'welcome', 'money', 'skills', 'services', 'entertainment', 'romance', 'shopping', 'games', 'offbeat', 'residence', 'community') NOT NULL ;
CREATE TABLE `fso_nhood_ban` (
`user_id` INT UNSIGNED NOT NULL,
`ban_reason` VARCHAR(1000) NOT NULL DEFAULT 'You have been banned from using neighborhood gameplay for misuse. For more information, see http://freeso.org/nhoodrules/',
`end_date` INT UNSIGNED NOT NULL,
PRIMARY KEY (`user_id`),
CONSTRAINT `fso_nhood_ban_user`
FOREIGN KEY (`user_id`)
REFERENCES `fso_users` (`user_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Table managing users who have been banned from Neighborhood Gameplay. (eg. inappropriate ratings, bribery in mayor campaign, abuse of bulletin board)';
ALTER TABLE `fso_events`
CHANGE COLUMN `description` `description` VARCHAR(1500) NULL DEFAULT NULL ,
CHANGE COLUMN `mail_message` `mail_message` VARCHAR(1500) NULL DEFAULT NULL ;
CREATE TRIGGER `fso_election_votes_BEFORE_INSERT` BEFORE INSERT ON `fso_election_votes` FOR EACH ROW BEGIN
IF (SELECT COUNT(*) from fso_election_votes v INNER JOIN fso_avatars va ON v.from_avatar_id = va.avatar_id
WHERE v.election_cycle_id = @cycle_id AND v.type = @type AND va.user_id IN
(SELECT user_id FROM fso_users WHERE last_ip =
(SELECT last_ip FROM fso_avatars a JOIN fso_users u on a.user_id = u.user_id WHERE avatar_id = @avatar_id)
)) > 0 THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'A vote from this person or someone related already exists for this cycle.';
END IF;
END;
ALTER TABLE `fso_mayor_ratings`
ADD UNIQUE INDEX `fso_rating_user_to_ava` (`from_user_id` ASC, `to_avatar_id` ASC);
ALTER TABLE `fso_tasks`
CHANGE COLUMN `task_type` `task_type` ENUM('prune_database', 'bonus', 'shutdown', 'job_balance', 'multi_check', 'prune_abandoned_lots', 'neighborhood_tick') NOT NULL ;
CREATE TABLE `fso_election_cyclemail` (
`avatar_id` INT UNSIGNED NOT NULL,
`cycle_id` INT UNSIGNED NOT NULL,
`cycle_state` ENUM('shutdown', 'nomination', 'election', 'ended', 'failsafe') NOT NULL,
PRIMARY KEY (`avatar_id`, `cycle_id`, `cycle_state`),
INDEX `fso_cmail_cycle_idx` (`cycle_id` ASC),
CONSTRAINT `fso_cmail_ava`
FOREIGN KEY (`avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_cmail_cycle`
FOREIGN KEY (`cycle_id`)
REFERENCES `fso_election_cycles` (`cycle_id`)
ON DELETE CASCADE
ON UPDATE CASCADE);
ALTER TABLE `fso_election_cycles`
CHANGE COLUMN `current_state` `current_state` ENUM('shutdown', 'nomination', 'election', 'ended', 'failsafe') NOT NULL ;
ALTER TABLE `fso_neighborhoods`
DROP FOREIGN KEY `fso_neigh_cycle`,
DROP FOREIGN KEY `fso_neigh_mayor`,
DROP FOREIGN KEY `fso_neigh_town_hall`;
ALTER TABLE `fso_neighborhoods`
ADD CONSTRAINT `fso_neigh_cycle`
FOREIGN KEY (`election_cycle_id`)
REFERENCES `fso_election_cycles` (`cycle_id`)
ON DELETE SET NULL
ON UPDATE CASCADE,
ADD CONSTRAINT `fso_neigh_mayor`
FOREIGN KEY (`mayor_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE SET NULL
ON UPDATE CASCADE,
ADD CONSTRAINT `fso_neigh_town_hall`
FOREIGN KEY (`town_hall_id`)
REFERENCES `fso_lots` (`lot_id`)
ON DELETE SET NULL
ON UPDATE CASCADE;
ALTER TABLE `fso_election_candidates`
CHANGE COLUMN `disqualified` `state` ENUM('informed', 'running', 'disqualified', 'lost', 'won') NOT NULL DEFAULT 'informed' COMMENT 'Boolean. True if this mayor has been disqualified for some reason.' ;
ALTER TABLE `fso_election_cycles`
ADD COLUMN `neighborhood_id` INT NULL AFTER `election_type`,
ADD INDEX `fso_cycle_nhood_idx` (`neighborhood_id` ASC);
ALTER TABLE `fso_election_cycles`
ADD CONSTRAINT `fso_cycle_nhood`
FOREIGN KEY (`neighborhood_id`)
REFERENCES `fso_neighborhoods` (`neighborhood_id`)
ON DELETE CASCADE
ON UPDATE CASCADE;

View file

@ -0,0 +1,34 @@
ALTER TABLE `fso_bulletin_posts`
DROP FOREIGN KEY `fso_bulletin_poster`;
ALTER TABLE `fso_bulletin_posts`
CHANGE COLUMN `avatar_id` `avatar_id` INT(10) UNSIGNED NULL ,
ADD COLUMN `lot_id` INT(11) NULL AFTER `flags`,
ADD COLUMN `type` ENUM('mayor', 'system', 'community') NULL AFTER `lot_id`,
ADD INDEX `fso_bulletin_lot_idx` (`lot_id` ASC);
ALTER TABLE `fso_bulletin_posts`
ADD CONSTRAINT `fso_bulletin_poster`
FOREIGN KEY (`avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
ADD CONSTRAINT `fso_bulletin_lot`
FOREIGN KEY (`lot_id`)
REFERENCES `fso_lots` (`lot_id`)
ON DELETE SET NULL
ON UPDATE CASCADE;
ALTER TABLE `fso_bulletin_posts`
DROP FOREIGN KEY `fso_bulletin_lot`;
ALTER TABLE `fso_bulletin_posts`
CHANGE COLUMN `lot_id` `lot_id` INT(11) UNSIGNED NULL DEFAULT NULL ,
ADD INDEX `fso_bulletin_lot_idx` (`lot_id` ASC),
DROP INDEX `fso_bulletin_lot_idx` ;
ALTER TABLE `fso_bulletin_posts`
ADD CONSTRAINT `fso_bulletin_lot`
FOREIGN KEY (`lot_id`)
REFERENCES `fso_lots` (`location`)
ON DELETE SET NULL
ON UPDATE CASCADE;
ALTER TABLE `fso_bulletin_posts`
ADD COLUMN `deleted` TINYINT UNSIGNED NOT NULL DEFAULT 0 AFTER `type`;

View file

@ -0,0 +1,99 @@
CREATE TABLE `fso_update_addons` (
`addon_id` INT NOT NULL AUTO_INCREMENT,
`name` VARCHAR(45) NOT NULL DEFAULT 'Untitled' COMMENT 'Name of the update addon.',
`description` VARCHAR(1000) NULL,
`addon_zip_url` VARCHAR(256) NOT NULL COMMENT 'Addon zip which is extracted on top of the client update base.',
`server_zip_url` VARCHAR(256) NULL COMMENT 'Addon zip which is extracted on top of the server update base. (optional)',
`date` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Date the addon was created.',
PRIMARY KEY (`addon_id`))
COMMENT = 'Update addons are additional resources which are combined with the base game version (from a buildbot) to create the final binary a server will update to and deploy.';
CREATE TABLE `fso_update_branch` (
`branch_id` INT NOT NULL AUTO_INCREMENT,
`version_format` VARCHAR(128) NOT NULL DEFAULT 'dev/update-#' COMMENT 'Format string for version name. # is version number, $ is commit number (if available).',
`last_version_number` INT NOT NULL DEFAULT 0 COMMENT 'The last version number. This is incremented when a new build is generated for this branch.',
`current_dist_id` INT NULL COMMENT 'The current distribution in fso_updates.',
`addon_id` INT NULL COMMENT '(Optional) The addon to merge into the downloaded binary.',
`base_build_url` VARCHAR(256) NOT NULL COMMENT 'URL for client binary to base updates off of. If \"teamcity\" is enabled, the client AND server binary is found within the grouped artifacts zip this link points to.',
`base_server_build_url` VARCHAR(256) NULL COMMENT '(Optional) URL for server binary. Required for zip mode, not for teamcity.',
`build_mode` ENUM('zip', 'teamcity') NOT NULL DEFAULT 'zip' COMMENT 'The mode to use when obtaining binaries.',
`flags` INT NULL COMMENT '1 - Disable Incremental Updates',
PRIMARY KEY (`branch_id`),
INDEX `branch_addon_id_idx` (`addon_id` ASC),
CONSTRAINT `branch_addon_id`
FOREIGN KEY (`addon_id`)
REFERENCES `fso_update_addons` (`addon_id`)
ON DELETE SET NULL
ON UPDATE CASCADE)
COMMENT = 'Update branches for the server. Each branch points to a source to download new zips from, and can optionally point to an update addon to be merged into it. This also generates a version name.';
CREATE TABLE `fso_updates` (
`update_id` INT NOT NULL AUTO_INCREMENT COMMENT 'The ID of this update.',
`version_name` VARCHAR(128) NOT NULL COMMENT 'The name of this version, generated from the format in the branch.',
`addon_id` INT NULL COMMENT 'The addon pack this update includes.',
`branch_id` INT NOT NULL COMMENT 'The branch this update was generated off of.',
`full_zip` VARCHAR(256) NOT NULL COMMENT 'URL for the zip file containing the full client distribution. Should be used for new users and fixing failed updates.',
`incremental_zip` VARCHAR(256) NULL COMMENT 'A zip containing the files that were added or modified since the last update (see last_update_id)',
`manfest_url` VARCHAR(256) NULL COMMENT 'Manifest file for the incremental zip.',
`server_zip` VARCHAR(256) NULL COMMENT 'URL to a zip containing the server distribution. Downloaded and applied by the Watchdog on server restart. (may also be used for rollbacks)',
`last_update_id` INT NULL COMMENT 'The update that the incremental update was created from.',
`flags` INT NOT NULL DEFAULT 0 COMMENT '1 - db-init required\n2 - force non-incremental\n4 - incremental on protected\n8 - rolled back',
`date` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'The date the update was generated at.',
`publish_date` DATETIME NULL COMMENT 'The date the update was published at.',
`deploy_after` DATETIME NULL COMMENT '(Optional) The time after which to deploy this update to the server on restart. When an entry with this is set and the server shuts down, it starts the update process and sets this to NULL.',
PRIMARY KEY (`update_id`),
INDEX `fso_updates_addon_idx` (`addon_id` ASC),
INDEX `fso_updates_branch_fk_idx` (`branch_id` ASC),
CONSTRAINT `fso_updates_addon_fk`
FOREIGN KEY (`addon_id`)
REFERENCES `fso_update_addons` (`addon_id`)
ON DELETE SET NULL
ON UPDATE CASCADE,
CONSTRAINT `fso_updates_branch_fk`
FOREIGN KEY (`branch_id`)
REFERENCES `fso_update_branch` (`branch_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Updates generated by the server for branches. Should link to all published assets, and track incremental update paths. When deploy_after is set, the update will become the main update for that branch after the time elapses (on server restart).';
ALTER TABLE `fso_updates`
ADD INDEX `fso_updates_last_fk_idx` (`last_update_id` ASC);
ALTER TABLE `fso_updates`
ADD CONSTRAINT `fso_updates_last_fk`
FOREIGN KEY (`last_update_id`)
REFERENCES `fso_updates` (`update_id`)
ON DELETE SET NULL
ON UPDATE CASCADE;
ALTER TABLE `fso_update_branch`
CHANGE COLUMN `flags` `flags` INT(11) NOT NULL COMMENT '1 - Disable Incremental Updates' ;
ALTER TABLE `fso_update_branch`
ADD COLUMN `branch_name` VARCHAR(128) NOT NULL DEFAULT 'dev' AFTER `branch_id`;
ALTER TABLE `fso_updates`
CHANGE COLUMN `full_zip` `full_zip` VARCHAR(256) NULL DEFAULT NULL COMMENT 'URL for the zip file containing the full client distribution. Should be used for new users and fixing failed updates.' ,
CHANGE COLUMN `manfest_url` `manifest_url` VARCHAR(256) NULL DEFAULT NULL COMMENT 'Manifest file for the incremental zip.' ;
ALTER TABLE `fso_update_branch`
ADD COLUMN `minor_version_number` INT NOT NULL DEFAULT 0 AFTER `last_version_number`;
ALTER TABLE `fso_shards`
ADD COLUMN `update_id` INT NULL DEFAULT NULL AFTER `version_number`,
ADD INDEX `fso_shard_update_id_idx` (`update_id` ASC);
ALTER TABLE `fso_shards`
ADD CONSTRAINT `fso_shard_update_id`
FOREIGN KEY (`update_id`)
REFERENCES `fso_updates` (`update_id`)
ON DELETE SET NULL
ON UPDATE CASCADE;
ALTER TABLE `fso_hosts`
ADD COLUMN `update_id` INT NULL DEFAULT NULL AFTER `shard_id`,
ADD INDEX `FK_fso_host_update_id_idx` (`update_id` ASC);
ALTER TABLE `fso_hosts`
ADD CONSTRAINT `FK_fso_host_update_id`
FOREIGN KEY (`update_id`)
REFERENCES `fso_updates` (`update_id`)
ON DELETE SET NULL
ON UPDATE CASCADE;

View file

@ -0,0 +1,48 @@
CREATE TABLE `fso_election_freevotes` (
`avatar_id` INT UNSIGNED NOT NULL,
`neighborhood_id` INT NOT NULL,
`cycle_id` INT UNSIGNED NOT NULL,
`date` INT NOT NULL,
`expire_date` INT NOT NULL,
PRIMARY KEY (`avatar_id`),
INDEX `fso_freevote_cycle_idx` (`cycle_id` ASC),
INDEX `fso_freevote_nhood_idx` (`neighborhood_id` ASC),
CONSTRAINT `fso_freevote_avatar`
FOREIGN KEY (`avatar_id`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_freevote_cycle`
FOREIGN KEY (`cycle_id`)
REFERENCES `fso_election_cycles` (`cycle_id`)
ON DELETE CASCADE
ON UPDATE CASCADE,
CONSTRAINT `fso_freevote_nhood`
FOREIGN KEY (`neighborhood_id`)
REFERENCES `fso_neighborhoods` (`neighborhood_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'When a neighborhood is ineligible for an election, its residents get to choose a neighborhood election to participate in. Entries in this table allow avatars to vote in an election when they do not live in its neighborhood. Entries in this table should expire when the linked cycle ends.';
ALTER TABLE `fso_election_freevotes`
CHANGE COLUMN `date` `date` INT(11) UNSIGNED NOT NULL ,
CHANGE COLUMN `expire_date` `expire_date` INT(11) UNSIGNED NOT NULL ;
ALTER TABLE `fso_election_votes`
ADD COLUMN `value` INT NOT NULL DEFAULT 1 COMMENT 'The value of this vote. Some votes can be worth more than others (eg. free votes are worth less than normal ones)' AFTER `date`;
CREATE TABLE `fso_auth_attempts` (
`attempt_id` INT UNSIGNED NOT NULL AUTO_INCREMENT,
`ip` VARCHAR(100) NOT NULL,
`user_id` INT UNSIGNED NOT NULL,
`expire_time` INT UNSIGNED NOT NULL,
`count` INT NOT NULL DEFAULT 0,
`active` TINYINT UNSIGNED NOT NULL DEFAULT 0,
`invalidated` TINYINT UNSIGNED NOT NULL DEFAULT 0,
PRIMARY KEY (`attempt_id`),
INDEX `fk_user_attempt_idx` (`user_id` ASC),
CONSTRAINT `fk_user_attempt`
FOREIGN KEY (`user_id`)
REFERENCES `fso_users` (`user_id`)
ON DELETE CASCADE
ON UPDATE CASCADE);

View file

@ -0,0 +1,23 @@
CREATE TABLE `fso_tuning_presets` (
`preset_id` INT NOT NULL AUTO_INCREMENT,
`name` VARCHAR(128) NULL,
`description` VARCHAR(1000) NULL,
`flags` INT NOT NULL DEFAULT 0,
PRIMARY KEY (`preset_id`))
COMMENT = 'Presets are collections of tuning info that can be applied and removed at the same time as part of an event.';
CREATE TABLE `fso_tuning_preset_items` (
`item_id` INT NOT NULL AUTO_INCREMENT,
`preset_id` INT NOT NULL,
`tuning_type` VARCHAR(128) NOT NULL,
`tuning_table` INT NOT NULL,
`tuning_index` INT NOT NULL,
`value` FLOAT NOT NULL,
PRIMARY KEY (`item_id`),
INDEX `fso_preset_item_to_preset_fk_idx` (`preset_id` ASC),
CONSTRAINT `fso_preset_item_to_preset_fk`
FOREIGN KEY (`preset_id`)
REFERENCES `fso_tuning_presets` (`preset_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Individual tuning items that belong to a preset configuration, to be applied as a group. Similar to fso_tuning, built to copy right into it.';

View file

@ -0,0 +1,2 @@
ALTER TABLE `fso_objects`
ADD COLUMN `upgrade_level` INT(11) UNSIGNED NOT NULL DEFAULT 0 AFTER `dyn_flags_2`;

View file

@ -0,0 +1,15 @@
CREATE TABLE `fso_generic_avatar_participation` (
`participation_name` TEXT(64) NOT NULL,
`participation_avatar` INT UNSIGNED NOT NULL,
PRIMARY KEY (`participation_name`(64), `participation_avatar`),
INDEX `fso_generic_ava_idx` (`participation_avatar` ASC),
INDEX `fso_generic_name_idx` (`participation_name`(64) ASC),
CONSTRAINT `fso_generic_avatarp_id`
FOREIGN KEY (`participation_avatar`)
REFERENCES `fso_avatars` (`avatar_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'If you need a generic way to track avatar participation in things, here it is. Useful for events and tasks that don\'t have their own per-avatar tracking and need it.';
ALTER TABLE `fso_tasks`
CHANGE COLUMN `task_type` `task_type` ENUM('prune_database', 'bonus', 'shutdown', 'job_balance', 'multi_check', 'prune_abandoned_lots', 'neighborhood_tick', 'birthday_gift') NOT NULL ;

View file

@ -0,0 +1,15 @@
CREATE TABLE `fso_object_attributes` (
`object_id` INT UNSIGNED NOT NULL COMMENT 'ID of the object this attribute is for.',
`index` INT UNSIGNED NOT NULL COMMENT 'Index of the Attribute.',
`value` INT NOT NULL COMMENT 'Value of the Attribute. Ingame these can only be short size, but I\'ve left them full int here just in case we need to expand.',
PRIMARY KEY (`object_id`, `index`),
INDEX `fso_object_id_attr_idx` (`object_id` ASC),
CONSTRAINT `fso_object_id_attr`
FOREIGN KEY (`object_id`)
REFERENCES `fso_objects` (`object_id`)
ON DELETE CASCADE
ON UPDATE CASCADE)
COMMENT = 'Attributes for objects in the fso_objects table. These are used for \'token\' objects, special objects which can track values such as secondary currencies and car keys (pointing to the car you are driving, for example)\nThese are only saved for objects of type token - other objects use filesystem objects to store attributes.';
ALTER TABLE `fso_objects`
ADD COLUMN `has_db_attributes` TINYINT UNSIGNED NOT NULL DEFAULT 0 COMMENT 'If >0, attributes should be fetched from fso_object_attributes rather than trusting NFS state. 2 indicates value token.' AFTER `upgrade_level`;

View file

@ -0,0 +1,10 @@
CREATE TABLE IF NOT EXISTS `fso_global_cooldowns` (
`object_guid` int(11) unsigned NOT NULL,
`avatar_id` int(10) unsigned NOT NULL,
`user_id` int(10) unsigned NOT NULL,
`category` int(10) unsigned NOT NULL,
`expiry` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
PRIMARY KEY (`object_guid`, `avatar_id`, `user_id`, `category`),
CONSTRAINT `FK_global_cooldowns_fso_avatars` FOREIGN KEY (`avatar_id`) REFERENCES `fso_avatars` (`avatar_id`) ON DELETE CASCADE ON UPDATE CASCADE,
CONSTRAINT `FK_global_cooldowns_fso_users` FOREIGN KEY (`user_id`) REFERENCES `fso_users` (`user_id`) ON DELETE CASCADE ON UPDATE CASCADE
)