/* Drop all the tables before creating */ DROP TABLE IF EXISTS `rmps`.`script_logs`; DROP TABLE IF EXISTS `rmps`.`scripts`; DROP TABLE IF EXISTS `rmps`.`script_types`; DROP TABLE IF EXISTS `rmps`.`jobs`; DROP TABLE IF EXISTS `rmps`.`job_types`; DROP TABLE IF EXISTS `rmps`.`static_groups`; DROP TABLE IF EXISTS `rmps`.`dynamic_groups`; DROP TABLE IF EXISTS `rmps`.`agents`; DROP TABLE IF EXISTS `rmps`.`users`; CREATE TABLE `rmps`.`users` ( `id` INT (11) NOT NULL AUTO_INCREMENT COMMENT 'User ID', `username` VARCHAR (255) NOT NULL COMMENT 'Login name', `name` VARCHAR (255) NOT NULL COMMENT 'Full name', `pass_hash` VARCHAR (255) NOT NULL COMMENT 'User pass - hash(pass+salt)', `pass_salt` VARCHAR (32) NOT NULL COMMENT 'User pass salt (/dev/urandom)', `added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Registration timestamp', `status` TINYINT (1) DEFAULT 1 COMMENT 'User active status', `last_log` TIMESTAMP DEFAULT 0 COMMENT 'Last login timestamp', `last_out` TIMESTAMP DEFAULT 0 COMMENT 'Last logout timestamp', `email` VARCHAR (255) NOT NULL COMMENT 'User e-mail', `comment` VARCHAR (255) DEFAULT NULL COMMENT 'User additional info', PRIMARY KEY (`id`) ); CREATE TABLE `rmps`.`static_groups` ( `id` INT (11) NOT NULL AUTO_INCREMENT COMMENT 'Static group ID', `name` VARCHAR (255) NOT NULL DEFAULT 'New Static Group' COMMENT 'Name of the Static group', `created` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Creation timestamp', `owner` INT (11) NOT NULL COMMENT 'User ID of the creator (FK)', `last_mod_time` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Last modification timestmap', `last_mod_user` INT (11) NOT NULL COMMENT 'User ID of last modifier', `comment` VARCHAR (255) DEFAULT NULL COMMENT 'Static group additional info', PRIMARY KEY (`id`), CONSTRAINT FOREIGN KEY (`owner`) REFERENCES `rmps`.`users`(`id`) ); CREATE TABLE `rmps`.`dynamic_groups` ( `id` INT (11) NOT NULL AUTO_INCREMENT COMMENT 'Dynamic group ID', PRIMARY KEY (`id`) ); CREATE TABLE `rmps`.`agents` ( `id` INT (11) NOT NULL AUTO_INCREMENT COMMENT 'Managed server ID or agent ID', `name` VARCHAR (255) NOT NULL DEFAULT 'New agent' COMMENT 'Custom name for the agent', `ip` INT (11) UNSIGNED NOT NULL COMMENT 'IP of the agent stored with INET_ATON(x)', `mac` VARCHAR (12) NOT NULL COMMENT 'MAC address of the agent', `fqdn` VARCHAR (255) NOT NULL COMMENT 'FQDN of the agent', `os` VARCHAR (100) NOT NULL COMMENT 'OS of the agent', `added` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Agent registration timestamp', `active` TINYINT (1) NOT NULL DEFAULT 1 COMMENT 'Agent status (if online or not)', `comment` VARCHAR (255) DEFAULT NULL COMMENT 'Agent additional info', PRIMARY KEY (`id`) ); CREATE TABLE `rmps`.`script_types` ( `id` INT (4) NOT NULL AUTO_INCREMENT COMMENT 'Script type ID', `descr` VARCHAR (30) NOT NULL COMMENT 'Script type description', PRIMARY KEY (`id`) ); CREATE TABLE `rmps`.`scripts` ( `id` INT (4) NOT NULL AUTO_INCREMENT COMMENT 'Script ID', `name` VARCHAR (100) NOT NULL DEFAULT 'New script' COMMENT 'Script custom name', `typeID` INT (4) NOT NULL COMMENT 'Script type ID (FK)', `created` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Script creation timestamp', `owner` INT (11) NOT NULL COMMENT 'User ID of the creator', `last_mod_time` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Last modification timestamp', `content` TEXT DEFAULT NULL COMMENT 'Script content', `comment` VARCHAR (255) DEFAULT NULL COMMENT 'Script additional info', PRIMARY KEY (`id`), CONSTRAINT FOREIGN KEY (`typeID`) REFERENCES `rmps`.`script_types`(`id`) ); CREATE TABLE `rmps`.`script_logs` ( `id` INT (11) NOT NULL AUTO_INCREMENT COMMENT 'Log ID', `jobID` INT (11) NOT NULL COMMENT 'Job ID', `started` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Script start timestamp', `ended` TIMESTAMP DEFAULT 0 COMMENT 'Script finish timestamp', `stdout` TEXT DEFAULT NULL COMMENT 'Script stdout', `stderr` TEXT DEFAULT NULL COMMENT 'Script stderr', `exit_code` INT (2) DEFAULT NULL COMMENT 'Script exit code ($?)', PRIMARY KEY (`id`) ); CREATE TABLE `rmps`.`job_types` ( `id` INT (11) NOT NULL AUTO_INCREMENT COMMENT 'Job type ID', `descr` VARCHAR (30) NOT NULL COMMENT 'Job type description', PRIMARY KEY (`id`) ); CREATE TABLE `rmps`.`jobs` ( `id` INT (11) NOT NULL AUTO_INCREMENT COMMENT 'Job ID', `typeID` INT (4) NOT NULL COMMENT 'Job type ID (FK)', `owner` INT (11) NOT NULL COMMENT 'User ID of the job creator (FK)', `started` TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT 'Job start time', `ended` TIMESTAMP DEFAULT 0 COMMENT 'Job finish time', `status` TINYINT(1) DEFAULT NULL COMMENT 'Job finish status', PRIMARY KEY (`id`), CONSTRAINT FOREIGN KEY (`typeID`) REFERENCES `rmps`.`job_types`(`id`), CONSTRAINT FOREIGN KEY (`owner`) REFERENCES `rmps`.`users`(`id`) ); /* Fill the job types */ INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('UNIX Script'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Install a package'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Query a package'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Delete a package'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('List all packages'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Update a package'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Update all packages'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Detect OS'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Detect UNIX kernel'); INSERT INTO `rmps`.`job_types` (`descr`) VALUES ('Get memory status'); /* Setup the admin user */ /* Define the procedures */ DELIMITER $$ USE `rmps` $$ DROP PROCEDURE IF EXISTS `rmps`.`addUser` $$ CREATE DEFINER=`rmps`@`localhost` PROCEDURE `addUser` ( IN loginName VARCHAR (255), IN fullName VARCHAR (255), IN eMail VARCHAR (255), IN passHash VARCHAR (128), IN passSalt VARCHAR (32), IN more VARCHAR (255), OUT output TINYINT (1) ) BEGIN DECLARE tmp TINYINT (1); SELECT `status` INTO tmp FROM `rmps`.`users` WHERE `username` = loginName AND `status` = 1 LIMIT 1; IF tmp IS NULL THEN INSERT INTO `rmps`.`users` (`username`, `name`, `email`, `pass_hash`, `pass_salt`, `comment`) VALUES (loginName, fullName, eMail, passHash, passSalt, more); SET output = 0; ELSE SET output = 1; END IF; END $$ call addUser(@loginName, @fullName, @eMail, @passHash, @passSalt, 0, @output); DROP PROCEDURE IF EXISTS `rmps`.`deactivateUser` $$ CREATE DEFINER=`rmps`@`localhost` PROCEDURE `deactivateUser` ( IN loginName VARCHAR (255) ) BEGIN DECLARE tmp TINYINT (1); SELECT `id` INTO tmp FROM `rmps`.`users` WHERE `username` = loginName AND `status` = 1 LIMIT 1; IF tmp IS NOT NULL THEN UPDATE `rmps`.`users` SET `status` = 0 WHERE `id` = tmp; END IF; END $$ DELIMITER ;