CREATE TABLE `config` ( `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, `key` VARCHAR(40) NOT NULL, `value` VARCHAR(40) DEFAULT NULL, PRIMARY KEY (`id`), UNIQUE (`key`) ) ENGINE INNODB DEFAULT CHARSET=utf8; INSERT INTO `config` (`key`,`value`) VALUES ('schema_version', '2'); CREATE TABLE `rooms` ( `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, `name` VARCHAR(120) NOT NULL, `owner` VARCHAR(60) DEFAULT NULL, `create_date` DATETIME DEFAULT NULL, `last_activity` DATETIME DEFAULT NULL, `locked` TINYINT UNSIGNED DEFAULT '0', `ask_for_name` TINYINT UNSIGNED DEFAULT '0', `join_password` VARCHAR(160) DEFAULT NULL, `owner_password` VARCHAR(160) DEFAULT NULL, `etherpad_group` VARCHAR(40) DEFAULT NULL, `token` VARCHAR(160) NOT NULL, `realm` VARCHAR(160) DEFAULT NULL, `persistent` TINYINT UNSIGNED DEFAULT '0', PRIMARY KEY (`id`), UNIQUE (`name`), INDEX (`last_activity`) ) ENGINE INNODB DEFAULT CHARSET=utf8; CREATE TABLE `room_participants` ( `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, `room_id` INT UNSIGNED NOT NULL, `participant` VARCHAR(60) NOT NULL, `peer_id` VARCHAR(60) DEFAULT NULL, `role` VARCHAR(30) DEFAULT 'participant', `last_activity` DATETIME DEFAULT NULL, PRIMARY KEY (`id`), UNIQUE (`room_id`, `participant`), UNIQUE (`room_id`, `peer_id`), UNIQUE (`participant`,`peer_id`), FOREIGN KEY (`room_id`) REFERENCES `rooms` (`id`) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE INNODB DEFAULT CHARSET=utf8; CREATE TABLE `email_notifications` ( `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, `room_id` INT UNSIGNED NOT NULL, `email` VARCHAR(254), PRIMARY KEY (`id`), UNIQUE (`room_id`, `email`), FOREIGN KEY (`room_id`) REFERENCES `rooms` (`id`) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE INNODB DEFAULT CHARSET=utf8; CREATE TABLE `email_invitations` ( `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, `room_id` INT UNSIGNED NOT NULL, `email` VARCHAR(254) NOT NULL, `token` VARCHAR(160) NOT NULL, `from` VARCHAR(60) NOT NULL, `response` VARCHAR(20) DEFAULT NULL, `message` TEXT DEFAULT NULL, `processed` TINYINT DEFAULT '0', `date` DATETIME DEFAULT NULL, PRIMARY KEY (`id`), UNIQUE (`token`), FOREIGN KEY (`room_id`) REFERENCES `rooms` (`id`) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE INNODB DEFAULT CHARSET=utf8; CREATE TABLE `api_keys` ( `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, `token` VARCHAR(160) NOT NULL, `admin` TINYINT UNSIGNED DEFAULT '0', `not_after` DATETIME DEFAULT NULL, PRIMARY KEY (`id`), UNIQUE (`token`), INDEX (`not_after`) ) ENGINE INNODB DEFAULT CHARSET=utf8; CREATE TABLE `room_keys` ( `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, `room_id` INT UNSIGNED NOT NULL, `key_id` INT UNSIGNED NOT NULL, `role` ENUM('owner', 'participant') DEFAULT 'participant', PRIMARY KEY (`id`), UNIQUE (`room_id`, `key_id`), FOREIGN KEY (`room_id`) REFERENCES `rooms` (`id`) ON UPDATE CASCADE ON DELETE CASCADE, FOREIGN KEY (`key_id`) REFERENCES `api_keys` (`id`) ON UPDATE CASCADE ON DELETE CASCADE ) ENGINE INNODB DEFAULT CHARSET=utf8; #DROP TABLE IF EXISTS `turnusers_lt`; #CREATE TABLE `turnusers_lt` ( # name VARCHAR(512) PRIMARY KEY, # hmackey char(32) #); CREATE VIEW `turnusers_lt` AS SELECT `name` AS `name`, MD5(CONCAT(CONCAT(CONCAT(CONCAT(`name`,':'),`realm`),':'),`token`)) AS `hmackey` FROM `rooms`; CREATE TABLE `turnusers_st` ( `name` VARCHAR(512) PRIMARY KEY, `password` VARCHAR(512) ) ENGINE INNODB DEFAULT CHARSET=latin1; CREATE TABLE `turn_secret` ( `value` VARCHAR(512) ) ENGINE INNODB DEFAULT CHARSET=latin1; CREATE TABLE `allowed_peer_ip` ( `ip_range` VARCHAR(256) ) ENGINE INNODB DEFAULT CHARSET=latin1; CREATE TABLE `denied_peer_ip` ( `ip_range` VARCHAR(256) ) ENGINE INNODB DEFAULT CHARSET=latin1;