2018-01-03 11:00:59 +00:00
CREATE DATABASE IF NOT EXISTS ` account ` /* !40100 DEFAULT CHARACTER SET utf8 */ ;
2018-01-24 07:06:49 +00:00
USE ` account ` ;
2018-01-03 11:00:59 +00:00
-- MySQL dump 10.13 Distrib 5.7.17, for Win64 (x86_64)
--
-- Host: db.verdnatura.es Database: account
-- ------------------------------------------------------
-- Server version 5.6.25-4-log
/* !40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */ ;
/* !40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */ ;
/* !40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */ ;
/* !40101 SET NAMES utf8 */ ;
/* !40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */ ;
/* !40103 SET TIME_ZONE='+00:00' */ ;
/* !40014 SET @OLD_UNIQUE_CHECKS=@@UNIQUE_CHECKS, UNIQUE_CHECKS=0 */ ;
/* !40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */ ;
/* !40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */ ;
/* !40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */ ;
--
-- Table structure for table `account`
--
DROP TABLE IF EXISTS ` account ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` account ` (
` id ` int ( 10 ) unsigned NOT NULL ,
PRIMARY KEY ( ` id ` ) ,
CONSTRAINT ` account_ibfk_3 ` FOREIGN KEY ( ` id ` ) REFERENCES ` user ` ( ` id ` ) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE = InnoDB DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Users allowed to have an account ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
2018-01-24 07:06:49 +00:00
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
/* !50003 CREATE */ /* !50017 DEFINER=`root`@`%` */ /* !50003 TRIGGER `account`.`accountAfterInsert`
AFTER INSERT ON ` account `
FOR EACH ROW
BEGIN
UPDATE user SET sync = FALSE
WHERE id = NEW . id ;
END * / ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
/* !50003 CREATE */ /* !50017 DEFINER=`root`@`%` */ /* !50003 TRIGGER `account`.`accountAfterDelete`
AFTER DELETE ON ` account `
FOR EACH ROW
BEGIN
UPDATE user SET sync = FALSE
WHERE id = OLD . id ;
END * / ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
2018-01-03 11:00:59 +00:00
--
-- Table structure for table `accountConfig`
--
DROP TABLE IF EXISTS ` accountConfig ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` accountConfig ` (
` id ` tinyint ( 3 ) unsigned NOT NULL AUTO_INCREMENT ,
` homedir ` varchar ( 50 ) COLLATE utf8_unicode_ci NOT NULL COMMENT ' The base folder for users home directories ' ,
` shell ` varchar ( 50 ) COLLATE utf8_unicode_ci NOT NULL COMMENT ' The default shell ' ,
` min ` smallint ( 6 ) NOT NULL ,
` max ` smallint ( 6 ) NOT NULL ,
` warn ` smallint ( 6 ) NOT NULL ,
` inact ` smallint ( 6 ) NOT NULL ,
PRIMARY KEY ( ` id ` )
) ENGINE = MyISAM AUTO_INCREMENT = 2 DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Global configuration parameters for accounts ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Temporary view structure for view `accountDovecot`
--
DROP TABLE IF EXISTS ` accountDovecot ` ;
/* !50001 DROP VIEW IF EXISTS `accountDovecot` */ ;
SET @ saved_cs_client = @ @ character_set_client ;
SET character_set_client = utf8 ;
/* !50001 CREATE VIEW `accountDovecot` AS SELECT
1 AS ` name ` ,
1 AS ` password ` * / ;
SET character_set_client = @ saved_cs_client ;
--
-- Table structure for table `accountLog`
--
DROP TABLE IF EXISTS ` accountLog ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` accountLog ` (
` id ` int ( 10 ) unsigned NOT NULL AUTO_INCREMENT ,
` msg ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL ,
` pid ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL ,
` user ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL ,
` host ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL ,
` rhost ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL ,
` time ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL ,
PRIMARY KEY ( ` id ` )
) ENGINE = MEMORY DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Temporary view structure for view `accountPam`
--
DROP TABLE IF EXISTS ` accountPam ` ;
/* !50001 DROP VIEW IF EXISTS `accountPam` */ ;
SET @ saved_cs_client = @ @ character_set_client ;
SET character_set_client = utf8 ;
/* !50001 CREATE VIEW `accountPam` AS SELECT
1 AS ` name ` ,
1 AS ` password ` * / ;
SET character_set_client = @ saved_cs_client ;
--
-- Table structure for table `ldapConfig`
--
DROP TABLE IF EXISTS ` ldapConfig ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` ldapConfig ` (
` id ` int ( 10 ) unsigned NOT NULL AUTO_INCREMENT ,
` host ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL COMMENT ' The hostname of LDAP server ' ,
` rdn ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL COMMENT ' The LDAP user ' ,
` password ` varchar ( 255 ) COLLATE utf8_unicode_ci NOT NULL COMMENT ' Base64 encoded password ' ,
` baseDn ` varchar ( 255 ) COLLATE utf8_unicode_ci DEFAULT NULL COMMENT ' The base DN to do the query ' ,
` filter ` varchar ( 255 ) COLLATE utf8_unicode_ci DEFAULT NULL COMMENT ' Filter to apply to the query ' ,
PRIMARY KEY ( ` id ` )
) ENGINE = InnoDB AUTO_INCREMENT = 2 DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' LDAP server configuration parameters ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `mailAlias`
--
DROP TABLE IF EXISTS ` mailAlias ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` mailAlias ` (
` id ` int ( 10 ) unsigned NOT NULL AUTO_INCREMENT ,
` alias ` varchar ( 50 ) CHARACTER SET utf8 NOT NULL ,
` isPublic ` tinyint ( 4 ) NOT NULL DEFAULT ' 1 ' ,
PRIMARY KEY ( ` id ` ) ,
UNIQUE KEY ` alias ` ( ` alias ` )
) ENGINE = InnoDB AUTO_INCREMENT = 62 DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Mail aliases ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `mailAliasAccount`
--
DROP TABLE IF EXISTS ` mailAliasAccount ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` mailAliasAccount ` (
` mailAlias ` int ( 10 ) unsigned NOT NULL ,
` account ` int ( 10 ) unsigned NOT NULL ,
PRIMARY KEY ( ` mailAlias ` , ` account ` ) ,
KEY ` account ` ( ` account ` ) ,
CONSTRAINT ` account ` FOREIGN KEY ( ` account ` ) REFERENCES ` account ` ( ` id ` ) ON DELETE CASCADE ON UPDATE CASCADE ,
CONSTRAINT ` mailAlias ` FOREIGN KEY ( ` mailAlias ` ) REFERENCES ` mailAlias ` ( ` id ` ) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE = InnoDB DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Mail alias that is assigned to each account ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `mailConfig`
--
DROP TABLE IF EXISTS ` mailConfig ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` mailConfig ` (
` id ` int ( 10 ) unsigned NOT NULL AUTO_INCREMENT ,
` domain ` varchar ( 255 ) NOT NULL ,
PRIMARY KEY ( ` id ` )
) ENGINE = InnoDB AUTO_INCREMENT = 2 DEFAULT CHARSET = utf8 ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `mailForward`
--
DROP TABLE IF EXISTS ` mailForward ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` mailForward ` (
` account ` int ( 10 ) unsigned NOT NULL ,
` forwardTo ` varchar ( 250 ) CHARACTER SET utf8 NOT NULL ,
PRIMARY KEY ( ` account ` ) ,
CONSTRAINT ` mailForward_ibfk_1 ` FOREIGN KEY ( ` account ` ) REFERENCES ` account ` ( ` id ` ) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE = InnoDB DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Mail forwarding ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `role`
--
DROP TABLE IF EXISTS ` role ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` role ` (
` id ` int ( 10 ) unsigned NOT NULL AUTO_INCREMENT ,
` name ` varchar ( 14 ) COLLATE utf8_unicode_ci NOT NULL ,
` description ` varchar ( 100 ) COLLATE utf8_unicode_ci DEFAULT NULL ,
` hasLogin ` tinyint ( 3 ) unsigned NOT NULL DEFAULT ' 0 ' ,
` created ` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ,
` modified ` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP ,
PRIMARY KEY ( ` id ` ) ,
UNIQUE KEY ` name ` ( ` name ` )
) ENGINE = InnoDB AUTO_INCREMENT = 33 DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Roles ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `roleInherit`
--
DROP TABLE IF EXISTS ` roleInherit ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` roleInherit ` (
` role ` int ( 10 ) unsigned NOT NULL ,
` inheritsFrom ` int ( 10 ) unsigned NOT NULL ,
PRIMARY KEY ( ` role ` , ` inheritsFrom ` ) ,
KEY ` owner_id ` ( ` inheritsFrom ` ) ,
CONSTRAINT ` roleInherit_ibfk_1 ` FOREIGN KEY ( ` role ` ) REFERENCES ` role ` ( ` id ` ) ON DELETE CASCADE ON UPDATE CASCADE ,
CONSTRAINT ` roleInherit_ibfk_2 ` FOREIGN KEY ( ` inheritsFrom ` ) REFERENCES ` role ` ( ` id ` ) ON DELETE CASCADE ON UPDATE CASCADE
) ENGINE = InnoDB DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Role inheritance ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `roleRole`
--
DROP TABLE IF EXISTS ` roleRole ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` roleRole ` (
` role ` int ( 10 ) unsigned NOT NULL ,
` inheritsFrom ` int ( 10 ) unsigned NOT NULL ,
UNIQUE KEY ` role ` ( ` role ` , ` inheritsFrom ` )
) ENGINE = MyISAM DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Calculated role inheritance ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `sambaConfig`
--
DROP TABLE IF EXISTS ` sambaConfig ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` sambaConfig ` (
` id ` tinyint ( 3 ) unsigned NOT NULL AUTO_INCREMENT ,
` host ` varchar ( 255 ) CHARACTER SET utf8 DEFAULT NULL COMMENT ' The hosname of Samba server ' ,
` sshUser ` varchar ( 30 ) CHARACTER SET utf8 DEFAULT NULL COMMENT ' The SSH user to connect to servers ' ,
` sshPass ` varchar ( 255 ) COLLATE utf8_unicode_ci DEFAULT NULL COMMENT ' The SSH password base64 encoded ' ,
` uidBase ` int ( 10 ) unsigned NOT NULL DEFAULT ' 10000 ' COMMENT ' The base for Unix uids ' ,
PRIMARY KEY ( ` id ` )
) ENGINE = MyISAM AUTO_INCREMENT = 2 DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Global configuration parameters for accounts ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `user`
--
DROP TABLE IF EXISTS ` user ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` user ` (
` id ` int ( 10 ) unsigned NOT NULL AUTO_INCREMENT ,
` name ` varchar ( 30 ) CHARACTER SET utf8 NOT NULL ,
` nickname ` varchar ( 127 ) COLLATE utf8_unicode_ci NOT NULL ,
` password ` char ( 64 ) COLLATE utf8_unicode_ci NOT NULL ,
` role ` int ( 10 ) unsigned NOT NULL DEFAULT ' 2 ' ,
` active ` tinyint ( 1 ) NOT NULL DEFAULT ' 1 ' ,
` email ` varchar ( 255 ) CHARACTER SET utf8 DEFAULT NULL ,
` lang ` char ( 2 ) CHARACTER SET utf8 DEFAULT NULL ,
` sync ` tinyint ( 4 ) NOT NULL DEFAULT ' 0 ' ,
` recoverPass ` tinyint ( 3 ) unsigned NOT NULL DEFAULT ' 1 ' ,
` lastPassChange ` datetime DEFAULT NULL ,
` created ` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ,
` updated ` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP ,
PRIMARY KEY ( ` id ` ) ,
UNIQUE KEY ` name ` ( ` name ` ) ,
KEY ` role ` ( ` role ` ) ,
KEY ` email ` ( ` email ` ) ,
KEY ` nickname ` ( ` nickname ` ) ,
KEY ` lang ` ( ` lang ` ) ,
CONSTRAINT ` user_ibfk_2 ` FOREIGN KEY ( ` role ` ) REFERENCES ` role ` ( ` id ` ) ON UPDATE CASCADE
2018-01-24 07:06:49 +00:00
) ENGINE = InnoDB AUTO_INCREMENT = 50179 DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Global users ' ;
2018-01-03 11:00:59 +00:00
/* !40101 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
/* !50003 CREATE */ /* !50017 DEFINER=`root`@`%` */ /* !50003 TRIGGER `account`.`userBeforeInsert`
BEFORE INSERT ON ` user `
FOR EACH ROW
BEGIN
CALL userCheckName ( NEW . ` name ` ) ;
END * / ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
/* !50003 CREATE */ /* !50017 DEFINER=`root`@`%` */ /* !50003 TRIGGER `account`.`userBeforeUpdate`
BEFORE UPDATE ON ` user `
FOR EACH ROW
BEGIN
IF NOT ( NEW . ` name ` < = > OLD . ` name ` ) THEN
CALL userCheckName ( NEW . ` name ` ) ;
END IF ;
IF NOT ( NEW . ` password ` < = > OLD . ` password ` ) THEN
SET NEW . lastPassChange = NOW ( ) ;
END IF ;
IF NEW . ` sync ` < = > OLD . ` sync ` THEN
SET NEW . ` sync ` = FALSE ;
END IF ;
END * / ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
/* !50003 CREATE */ /* !50017 DEFINER=`root`@`%` */ /* !50003 TRIGGER `userAfterUpdate`
AFTER UPDATE ON ` user `
FOR EACH ROW
BEGIN
IF NOT ( NEW . ` role ` < = > OLD . ` role ` )
THEN
INSERT INTO vn2008 . mail SET
` to ` = ' jgallego@verdnatura.es ' ,
` reply_to ` = ' jgallego@verdnatura.es ' ,
` subject ` = ' Rol modificado ' ,
` text ` = CONCAT ( account . userGetName ( ) , ' ha modificado el rol del usuario ' ,
NEW . ` name ` , ' de ' , OLD . role , ' a ' , NEW . role ) ;
END IF ;
END * / ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
--
-- Table structure for table `userConfig`
--
DROP TABLE IF EXISTS ` userConfig ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` userConfig ` (
` id ` int ( 10 ) unsigned NOT NULL AUTO_INCREMENT ,
` loginKey ` varchar ( 255 ) DEFAULT NULL ,
PRIMARY KEY ( ` id ` )
) ENGINE = MyISAM AUTO_INCREMENT = 2 DEFAULT CHARSET = utf8 ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Table structure for table `userPassword`
--
DROP TABLE IF EXISTS ` userPassword ` ;
/* !40101 SET @saved_cs_client = @@character_set_client */ ;
/* !40101 SET character_set_client = utf8 */ ;
CREATE TABLE ` userPassword ` (
` id ` tinyint ( 3 ) unsigned NOT NULL AUTO_INCREMENT ,
` length ` tinyint ( 3 ) unsigned NOT NULL ,
` nAlpha ` tinyint ( 3 ) unsigned NOT NULL ,
` nUpper ` tinyint ( 3 ) unsigned NOT NULL ,
` nDigits ` tinyint ( 3 ) unsigned NOT NULL ,
` nPunct ` tinyint ( 3 ) unsigned NOT NULL ,
PRIMARY KEY ( ` id ` )
) ENGINE = MyISAM AUTO_INCREMENT = 2 DEFAULT CHARSET = utf8 COLLATE = utf8_unicode_ci COMMENT = ' Restrictions on user passwords ' ;
/* !40101 SET character_set_client = @saved_cs_client */ ;
--
-- Temporary view structure for view `userRole`
--
DROP TABLE IF EXISTS ` userRole ` ;
/* !50001 DROP VIEW IF EXISTS `userRole` */ ;
SET @ saved_cs_client = @ @ character_set_client ;
SET character_set_client = utf8 ;
/* !50001 CREATE VIEW `userRole` AS SELECT
1 AS ` id ` * / ;
SET character_set_client = @ saved_cs_client ;
--
-- Temporary view structure for view `userView`
--
DROP TABLE IF EXISTS ` userView ` ;
/* !50001 DROP VIEW IF EXISTS `userView` */ ;
SET @ saved_cs_client = @ @ character_set_client ;
SET character_set_client = utf8 ;
/* !50001 CREATE VIEW `userView` AS SELECT
1 AS ` id ` ,
1 AS ` name ` ,
1 AS ` active ` ,
1 AS ` email ` ,
1 AS ` nickname ` ,
1 AS ` lang ` ,
1 AS ` role ` ,
1 AS ` recoverPass ` * / ;
SET character_set_client = @ saved_cs_client ;
--
-- Dumping events for database 'account'
--
--
-- Dumping routines for database 'account'
--
/* !50003 DROP FUNCTION IF EXISTS `toUnixDays` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` toUnixDays ` ( vDate DATE ) RETURNS int ( 11 )
DETERMINISTIC
BEGIN
/* *
* Devuelve el timestamp unix en días de una fecha .
*
* @ param vData La fecha
* @ return Unix timestamp en días
* /
RETURN UNIX_TIMESTAMP ( vDate ) DIV 86400 ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP FUNCTION IF EXISTS `userCheckLogin` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` userCheckLogin ` ( ) RETURNS tinyint ( 1 )
READS SQL DATA
DETERMINISTIC
BEGIN
/* *
* Checks that variables @ userId and @ userName haven ' t been altered.
*
* @ return % TRUE if they are unaltered or unset , otherwise % FALSE
* /
DECLARE vSignature VARCHAR ( 128 ) ;
DECLARE vKey VARCHAR ( 255 ) ;
IF @ userId IS NOT NULL
AND @ userName IS NOT NULL
AND @ userSignature IS NOT NULL
THEN
SELECT loginKey INTO vKey FROM userConfig ;
SET vSignature = util . hmacSha2 ( 256 , CONCAT_WS ( ' / ' , @ userId , @ userName ) , vKey ) ;
RETURN vSignature = @ userSignature ;
END IF ;
RETURN FALSE ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP FUNCTION IF EXISTS `userGetId` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` USERGETID ` ( ) RETURNS int ( 11 )
READS SQL DATA
DETERMINISTIC
BEGIN
/* *
* Returns the current user id .
*
* @ return The user id
* /
DECLARE vUser INT DEFAULT NULL ;
IF userCheckLogin ( )
THEN
SET vUser = @ userId ;
ELSE
SELECT id INTO vUser FROM user
WHERE name = LEFT ( USER ( ) , INSTR ( USER ( ) , ' @ ' ) - 1 ) ;
END IF ;
RETURN vUser ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP FUNCTION IF EXISTS `userGetMysqlRole` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` userGetMysqlRole ` ( vUserName VARCHAR ( 255 ) ) RETURNS varchar ( 255 ) CHARSET utf8
BEGIN
/* *
* A partir de un nombre de usuario devuelve el rol
* de MySQL asociado y con el que deberia autenticarse
* cuando se utilice sistemas de autenticación externos .
*
* @ param vUserName El nombre de usuario
* @ return El rol de MySQL asociado
* /
DECLARE vRole VARCHAR ( 255 ) ;
SELECT CONCAT ( IF ( r . hasLogin , ' z- ' , ' ' ) , r . name ) INTO vRole
FROM role r
JOIN user u ON u . role = r . id
WHERE u . name = vUserName ;
RETURN vRole ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP FUNCTION IF EXISTS `userGetName` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` userGetName ` ( ) RETURNS varchar ( 30 ) CHARSET utf8
NO SQL
DETERMINISTIC
BEGIN
/* *
* Returns the current user name .
*
* @ return The user name
* /
DECLARE vUser VARCHAR ( 30 ) DEFAULT NULL ;
IF userCheckLogin ( )
THEN
SET vUser = @ userName ;
ELSE
SET vUser = LEFT ( USER ( ) , INSTR ( USER ( ) , ' @ ' ) - 1 ) ;
END IF ;
RETURN vUser ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP FUNCTION IF EXISTS `userGetNameFromId` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` userGetNameFromId ` ( vId INT ) RETURNS varchar ( 30 ) CHARSET utf8
BEGIN
/* *
* Obtener nombre de usuari a partir de su id
*
* @ param vId Id del usuario
* @ return Nombre de usuario
* /
DECLARE vName VARCHAR ( 30 ) ;
SELECT ` name ` INTO vName
FROM user
WHERE id = vId ;
RETURN vName ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP FUNCTION IF EXISTS `userHasRole` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` userHasRole ` ( vRoleName VARCHAR ( 255 ) ) RETURNS tinyint ( 1 )
DETERMINISTIC
BEGIN
/* *
* Comprueba si el usuario actual tiene asociado un rol .
*
* @ param vRoleName Nombre del rol a comprobar
* @ return % TRUE si tiene el rol , % FALSE en caso contrario
* /
DECLARE vRoleId INT ;
SELECT id INTO vRoleId
FROM role
WHERE ` name ` = vRoleName COLLATE ' utf8_unicode_ci ' ;
RETURN userHasRoleId ( vRoleId ) ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP FUNCTION IF EXISTS `userHasRoleId` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` FUNCTION ` userHasRoleId ` ( vRoleId INT ) RETURNS tinyint ( 1 )
DETERMINISTIC
BEGIN
/* *
* Comprueba si el usuario actual tiene asociado un rol .
*
* @ param vRoleId Identificador del rol a comprobar
* @ return % TRUE si tiene el rol , % FALSE en caso contrario
* /
DECLARE vHasRole BOOL DEFAULT FALSE ;
SELECT COUNT ( * ) > 0 INTO vHasRole
FROM userRole
WHERE id = vRoleId ;
RETURN vHasRole ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `privSync` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` privSync ` ( )
proc : BEGIN
/* *
* Sincroniza los permisos de los usuarios ' rol ' de MySQL
* en base a la jerarquía de roles . Los usuarios rol resultantes
* de la mezcla de permisos serán nombrados singuiendo el patrón
* z - [ nombre_rol ] .
*
* Para que el procedimiento funcione debe de existir un usuario
* any @ % que se usara como plantilla base .
*
* ¡ Atención ! Este procedimiento solo debe ser llamado cuando se
* modifiquen los privilegios de MySQL . Si se modifica la jerarquía
* de roles , se debe llamar al procedimiento roleSync ( ) que llama a
* este internamente .
* /
DECLARE vTplUser VARCHAR ( 255 ) DEFAULT ' any ' ;
DECLARE vHost VARCHAR ( 255 ) DEFAULT ' % ' ;
DECLARE vPrefix VARCHAR ( 2 ) DEFAULT ' z- ' ;
DECLARE vTplExists BOOL ;
DECLARE vTplHost VARCHAR ( 255 ) ;
DECLARE vPrefixedLike VARCHAR ( 255 ) ;
-- Comprueba que el usuario plantilla existe
SELECT COUNT ( * ) > 0 , ` Host `
INTO vTplExists , vTplHost
FROM mysql . user
WHERE ` User ` = vTplUser
LIMIT 1 ;
IF NOT vTplExists THEN
SIGNAL SQLSTATE ' 45000 '
SET MESSAGE_TEXT = ' TEMPLATE_USER_NOT_EXISTS ' ;
END IF ;
-- Borra todos los privilegios calculados
SET vPrefixedLike = CONCAT ( vPrefix , ' % ' ) ;
DELETE FROM mysql . user
WHERE ` User ` LIKE vPrefixedLike ;
DELETE FROM mysql . db
WHERE ` User ` LIKE vPrefixedLike ;
DELETE FROM mysql . tables_priv
WHERE ` User ` LIKE vPrefixedLike ;
DELETE FROM mysql . columns_priv
WHERE ` User ` LIKE vPrefixedLike ;
DELETE FROM mysql . procs_priv
WHERE ` User ` LIKE vPrefixedLike ;
DELETE FROM mysql . proxies_priv
WHERE ` Proxied_user ` LIKE vPrefixedLike ;
-- Tablas temporales
DROP TEMPORARY TABLE IF EXISTS tRole ;
CREATE TEMPORARY TABLE tRole
ENGINE = MEMORY
SELECT
` name ` role ,
CONCAT ( vPrefix , ` name ` ) prefixedRole
FROM role
WHERE hasLogin ;
DROP TEMPORARY TABLE IF EXISTS tRoleInherit ;
CREATE TEMPORARY TABLE tRoleInherit
( INDEX ( inheritsFrom ) )
ENGINE = MEMORY
SELECT
CONCAT ( vPrefix , r . ` name ` ) prefixedRole ,
ri . ` name ` inheritsFrom
FROM role r
JOIN roleRole rr ON rr . role = r . id
JOIN role ri ON ri . id = rr . inheritsFrom ;
-- Vueve a crear el usuario
INSERT INTO mysql . user (
` User ` ,
` Host ` ,
` Password ` ,
` ssl_type ` ,
` ssl_cipher ` ,
` x509_issuer ` ,
` x509_subject ` ,
` max_questions ` ,
` max_updates ` ,
` max_connections ` ,
` max_user_connections `
)
SELECT
r . prefixedRole ,
vTplHost ,
IF ( ' ' ! = u . ` Password ` ,
u . ` Password ` , t . ` Password ` ) ,
IF ( ' ' ! = u . ` ssl_type ` ,
u . ` ssl_type ` , t . ` ssl_type ` ) ,
IF ( ' ' ! = u . ` ssl_cipher ` ,
u . ` ssl_cipher ` , t . ` ssl_cipher ` ) ,
IF ( ' ' ! = u . ` x509_issuer ` ,
u . ` x509_issuer ` , t . ` x509_issuer ` ) ,
IF ( ' ' ! = u . ` x509_subject ` ,
u . ` x509_subject ` , t . ` x509_subject ` ) ,
IF ( 0 ! = u . ` max_questions ` ,
u . ` max_questions ` , t . ` max_questions ` ) ,
IF ( 0 ! = u . ` max_updates ` ,
u . ` max_updates ` , t . ` max_updates ` ) ,
IF ( 0 ! = u . ` max_connections ` ,
u . ` max_connections ` , t . ` max_connections ` ) ,
IF ( 0 ! = u . ` max_user_connections ` ,
u . ` max_user_connections ` , t . ` max_user_connections ` )
FROM tRole r
JOIN mysql . user t
ON t . ` User ` = vTplUser
AND t . ` Host ` = vTplHost
LEFT JOIN mysql . user u
ON u . ` User ` = r . role
AND u . ` Host ` = vHost ;
INSERT INTO mysql . proxies_priv (
` User ` ,
` Host ` ,
` Proxied_user ` ,
` Proxied_host ` ,
` Grantor `
)
SELECT
' ' ,
vHost ,
prefixedRole ,
vHost ,
CONCAT ( prefixedRole , ' @ ' , vTplHost )
FROM tRole ;
-- Copia los privilegios globales del usuario
DROP TEMPORARY TABLE IF EXISTS tUserPriv ;
CREATE TEMPORARY TABLE tUserPriv
( INDEX ( prefixedRole ) )
ENGINE = MEMORY
SELECT
r . prefixedRole ,
MAX ( u . ` Select_priv ` ) ` Select_priv ` ,
MAX ( u . ` Insert_priv ` ) ` Insert_priv ` ,
MAX ( u . ` Update_priv ` ) ` Update_priv ` ,
MAX ( u . ` Delete_priv ` ) ` Delete_priv ` ,
MAX ( u . ` Create_priv ` ) ` Create_priv ` ,
MAX ( u . ` Drop_priv ` ) ` Drop_priv ` ,
MAX ( u . ` Reload_priv ` ) ` Reload_priv ` ,
MAX ( u . ` Shutdown_priv ` ) ` Shutdown_priv ` ,
MAX ( u . ` Process_priv ` ) ` Process_priv ` ,
MAX ( u . ` File_priv ` ) ` File_priv ` ,
MAX ( u . ` Grant_priv ` ) ` Grant_priv ` ,
MAX ( u . ` References_priv ` ) ` References_priv ` ,
MAX ( u . ` Index_priv ` ) ` Index_priv ` ,
MAX ( u . ` Alter_priv ` ) ` Alter_priv ` ,
MAX ( u . ` Show_db_priv ` ) ` Show_db_priv ` ,
MAX ( u . ` Super_priv ` ) ` Super_priv ` ,
MAX ( u . ` Create_tmp_table_priv ` ) ` Create_tmp_table_priv ` ,
MAX ( u . ` Lock_tables_priv ` ) ` Lock_tables_priv ` ,
MAX ( u . ` Execute_priv ` ) ` Execute_priv ` ,
MAX ( u . ` Repl_slave_priv ` ) ` Repl_slave_priv ` ,
MAX ( u . ` Repl_client_priv ` ) ` Repl_client_priv ` ,
MAX ( u . ` Create_view_priv ` ) ` Create_view_priv ` ,
MAX ( u . ` Show_view_priv ` ) ` Show_view_priv ` ,
MAX ( u . ` Create_routine_priv ` ) ` Create_routine_priv ` ,
MAX ( u . ` Alter_routine_priv ` ) ` Alter_routine_priv ` ,
MAX ( u . ` Create_user_priv ` ) ` Create_user_priv ` ,
MAX ( u . ` Event_priv ` ) ` Event_priv ` ,
MAX ( u . ` Trigger_priv ` ) ` Trigger_priv ` ,
MAX ( u . ` Create_tablespace_priv ` ) ` Create_tablespace_priv `
FROM tRoleInherit r
JOIN mysql . user u
ON u . ` User ` = r . inheritsFrom
AND u . ` Host ` = vHost
GROUP BY r . prefixedRole ;
UPDATE mysql . user u
JOIN tUserPriv t
ON u . ` User ` = t . prefixedRole
AND u . ` Host ` = vHost
SET
u . ` Select_priv `
= t . ` Select_priv ` ,
u . ` Insert_priv `
= t . ` Insert_priv ` ,
u . ` Update_priv `
= t . ` Update_priv ` ,
u . ` Delete_priv `
= t . ` Delete_priv ` ,
u . ` Create_priv `
= t . ` Create_priv ` ,
u . ` Drop_priv `
= t . ` Drop_priv ` ,
u . ` Reload_priv `
= t . ` Reload_priv ` ,
u . ` Shutdown_priv `
= t . ` Shutdown_priv ` ,
u . ` Process_priv `
= t . ` Process_priv ` ,
u . ` File_priv `
= t . ` File_priv ` ,
u . ` Grant_priv `
= t . ` Grant_priv ` ,
u . ` References_priv `
= t . ` References_priv ` ,
u . ` Index_priv `
= t . ` Index_priv ` ,
u . ` Alter_priv `
= t . ` Alter_priv ` ,
u . ` Show_db_priv `
= t . ` Show_db_priv ` ,
u . ` Super_priv `
= t . ` Super_priv ` ,
u . ` Create_tmp_table_priv `
= t . ` Create_tmp_table_priv ` ,
u . ` Lock_tables_priv `
= t . ` Lock_tables_priv ` ,
u . ` Execute_priv `
= t . ` Execute_priv ` ,
u . ` Repl_slave_priv `
= t . ` Repl_slave_priv ` ,
u . ` Repl_client_priv `
= t . ` Repl_client_priv ` ,
u . ` Create_view_priv `
= t . ` Create_view_priv ` ,
u . ` Show_view_priv `
= t . ` Show_view_priv ` ,
u . ` Create_routine_priv `
= t . ` Create_routine_priv ` ,
u . ` Alter_routine_priv `
= t . ` Alter_routine_priv ` ,
u . ` Create_user_priv `
= t . ` Create_user_priv ` ,
u . ` Event_priv `
= t . ` Event_priv ` ,
u . ` Trigger_priv `
= t . ` Trigger_priv ` ,
u . ` Create_tablespace_priv `
= t . ` Create_tablespace_priv ` ;
DROP TEMPORARY TABLE tUserPriv ;
-- Copia los privilegios a nivel de esquema
INSERT INTO mysql . db (
` User ` ,
` Host ` ,
` Db ` ,
` Select_priv ` ,
` Insert_priv ` ,
` Update_priv ` ,
` Delete_priv ` ,
` Create_priv ` ,
` Drop_priv ` ,
` Grant_priv ` ,
` References_priv ` ,
` Index_priv ` ,
` Alter_priv ` ,
` Create_tmp_table_priv ` ,
` Lock_tables_priv ` ,
` Create_view_priv ` ,
` Show_view_priv ` ,
` Create_routine_priv ` ,
` Alter_routine_priv ` ,
` Execute_priv ` ,
` Event_priv ` ,
` Trigger_priv `
)
SELECT
r . prefixedRole ,
vTplHost ,
t . ` Db ` ,
MAX ( t . ` Select_priv ` ) ,
MAX ( t . ` Insert_priv ` ) ,
MAX ( t . ` Update_priv ` ) ,
MAX ( t . ` Delete_priv ` ) ,
MAX ( t . ` Create_priv ` ) ,
MAX ( t . ` Drop_priv ` ) ,
MAX ( t . ` Grant_priv ` ) ,
MAX ( t . ` References_priv ` ) ,
MAX ( t . ` Index_priv ` ) ,
MAX ( t . ` Alter_priv ` ) ,
MAX ( t . ` Create_tmp_table_priv ` ) ,
MAX ( t . ` Lock_tables_priv ` ) ,
MAX ( t . ` Create_view_priv ` ) ,
MAX ( t . ` Show_view_priv ` ) ,
MAX ( t . ` Create_routine_priv ` ) ,
MAX ( t . ` Alter_routine_priv ` ) ,
MAX ( t . ` Execute_priv ` ) ,
MAX ( t . ` Event_priv ` ) ,
MAX ( t . ` Trigger_priv ` )
FROM tRoleInherit r
JOIN mysql . db t
ON t . ` User ` = r . inheritsFrom
AND t . ` Host ` = vHost
GROUP BY r . prefixedRole , t . ` Db ` ;
-- Copia los privilegios a nivel de tabla
INSERT INTO mysql . tables_priv (
` User ` ,
` Host ` ,
` Db ` ,
` Table_name ` ,
` Grantor ` ,
` Timestamp ` ,
` Table_priv ` ,
` Column_priv `
)
SELECT
r . prefixedRole ,
vTplHost ,
t . ` Db ` ,
t . ` Table_name ` ,
t . ` Grantor ` ,
MAX ( t . ` Timestamp ` ) ,
GROUP_CONCAT ( CONCAT ( t . ` Table_priv ` , ' , ' ) ) ,
GROUP_CONCAT ( CONCAT ( t . ` Column_priv ` , ' , ' ) )
FROM tRoleInherit r
JOIN mysql . tables_priv t
ON t . ` User ` = r . inheritsFrom
AND t . ` Host ` = vHost
GROUP BY r . prefixedRole , t . ` Db ` , t . ` Table_name ` ;
-- Copia los privilegios a nivel de columna
INSERT INTO mysql . columns_priv (
` User ` ,
` Host ` ,
` Db ` ,
` Table_name ` ,
` Column_name ` ,
` Timestamp ` ,
` Column_priv `
)
SELECT
r . prefixedRole ,
vTplHost ,
t . ` Db ` ,
t . ` Table_name ` ,
t . ` Column_name ` ,
MAX ( t . ` Timestamp ` ) ,
GROUP_CONCAT ( CONCAT ( t . ` Column_priv ` , ' , ' ) )
FROM tRoleInherit r
JOIN mysql . columns_priv t
ON t . ` User ` = r . inheritsFrom
AND t . ` Host ` = vHost
GROUP BY r . prefixedRole , t . ` Db ` , t . ` Table_name ` , t . ` Column_name ` ;
-- Copia los privilegios de los procedimientos
INSERT IGNORE INTO mysql . procs_priv (
` User ` ,
` Host ` ,
` Db ` ,
` Routine_name ` ,
` Routine_type ` ,
` Grantor ` ,
` Timestamp ` ,
` Proc_priv `
)
SELECT
r . prefixedRole ,
vTplHost ,
t . ` Db ` ,
t . ` Routine_name ` ,
t . ` Routine_type ` ,
t . ` Grantor ` ,
t . ` Timestamp ` ,
t . ` Proc_priv `
FROM tRoleInherit r
JOIN mysql . procs_priv t
ON t . ` User ` = r . inheritsFrom
AND t . ` Host ` = vHost ;
-- Libera memoria
DROP TEMPORARY TABLE
tRole ,
tRoleInherit ;
FLUSH PRIVILEGES ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `roleGetDescendents` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` roleGetDescendents ` ( vRole INT )
BEGIN
/* *
* Obtiene los identificadores de todos los subroles
* implementados por un rol ( Incluido el mismo ) .
*
* @ param vRole Identificador del rol
* @ table tmp . role Subroles implementados por el rol
* /
DECLARE vIsRoot BOOL ;
DROP TEMPORARY TABLE IF EXISTS
tmp . role , parents , childs ;
CREATE TEMPORARY TABLE tmp . role
( UNIQUE ( id ) )
ENGINE = MEMORY
SELECT vRole AS id ;
CREATE TEMPORARY TABLE parents
ENGINE = MEMORY
SELECT vRole AS id ;
CREATE TEMPORARY TABLE childs
LIKE parents ;
REPEAT
DELETE FROM childs ;
INSERT INTO childs
SELECT DISTINCT r . inheritsFrom id
FROM parents p
JOIN roleInherit r ON r . role = p . id
LEFT JOIN tmp . role t ON t . id = r . inheritsFrom
WHERE t . id IS NULL ;
DELETE FROM parents ;
INSERT INTO parents
SELECT * FROM childs ;
INSERT INTO tmp . role
SELECT * FROM childs ;
UNTIL ROW_COUNT ( ) < = 0
END REPEAT ;
-- If it is root all the roles are added
SELECT COUNT ( * ) > 0 INTO vIsRoot
FROM tmp . role
WHERE id = 0 ;
IF vIsRoot THEN
INSERT IGNORE INTO tmp . role ( id )
SELECT id FROM role ;
END IF ;
-- Cleaning
DROP TEMPORARY TABLE
parents , childs ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `roleSync` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` roleSync ` ( )
BEGIN
/* *
* Sincroniza la tabla @ roleRole con la jerarquía de roles
* actual . Este procedimiento debe ser llamado cada vez que
* se modifique la tabla @ roleInherit para que los cambios
* realizados sobre esta sean efectivos .
* /
DECLARE vRoleId INT ;
DECLARE vDone BOOL ;
DECLARE cur CURSOR FOR
SELECT id FROM role ;
DECLARE CONTINUE HANDLER FOR NOT FOUND SET vDone = TRUE ;
TRUNCATE TABLE roleRole ;
OPEN cur ;
l : LOOP
SET vDone = FALSE ;
FETCH cur INTO vRoleId ;
IF vDone THEN
LEAVE l ;
END IF ;
CALL roleGetDescendents ( vRoleId ) ;
INSERT INTO roleRole ( role , inheritsFrom )
SELECT vRoleId , id FROM tmp . role ;
DROP TEMPORARY TABLE tmp . role ;
END LOOP ;
CLOSE cur ;
CALL privSync ( ) ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `userChangePassword` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` userChangePassword ` ( vOldPassword VARCHAR ( 255 ) , vPassword VARCHAR ( 255 ) )
BEGIN
/* *
* Changes the current user password , if user is in recovery
* mode ignores the current password .
*
* @ param vOldPassword The current password
* @ param vPassword The new password
* /
DECLARE vPasswordOk BOOL ;
SELECT ` password ` = MD5 ( vOldPassword ) OR recoverPass
INTO vPasswordOk
FROM user WHERE id = account . userGetId ( ) ;
IF NOT vPasswordOk THEN
SIGNAL SQLSTATE ' 45000 '
SET MESSAGE_TEXT = ' Invalid password ' ;
END IF ;
CALL userSetPassword ( userGetName ( ) , vPassword ) ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `userCheckName` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` userCheckName ` ( vUserName VARCHAR ( 255 ) )
BEGIN
/* *
* Comprueba que el nombre de usuario reune los requisitos
* de sintaxis necesarios , en caso contrario lanza una
* excepción .
* El nombre de usuario solo debe contener letras minúsculas
* o , a partir del segundo carácter , números o subguiones .
2018-01-24 07:06:49 +00:00
* /
2018-01-03 11:00:59 +00:00
IF vUserName NOT REGEXP ' ^[a-z0-9_]*$ ' THEN
SIGNAL SQLSTATE ' 45000 '
SET MESSAGE_TEXT = ' INVALID_USER_NAME ' ;
END IF ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `userCheckPassword` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` userCheckPassword ` ( vPassword VARCHAR ( 255 ) )
BEGIN
/* *
* Comprueba si la contraseña cumple los requisitos de seguridad
* establecidos . Lanza una excepción si no se cumplen .
*
* @ param vPassword Contraseña a comprobar
* /
DECLARE vChr CHAR ( 1 ) ;
DECLARE vPasswordOk TINYINT ;
DECLARE vI TINYINT DEFAULT 1 ;
DECLARE vNAlpha TINYINT DEFAULT 0 ;
DECLARE vNUpper TINYINT DEFAULT 0 ;
DECLARE vNDigits TINYINT DEFAULT 0 ;
DECLARE vNPunct TINYINT DEFAULT 0 ;
WHILE vI < = CHAR_LENGTH ( vPassword )
DO
SET vChr = SUBSTRING ( vPassword , vI , 1 ) ;
IF vChr REGEXP ' [[:alpha:]] '
THEN
SET vNAlpha = vNAlpha + 1 ;
IF vChr REGEXP ' [A-Z] '
THEN
SET vNUpper = vNUpper + 1 ;
END IF ;
ELSEIF vChr REGEXP ' [[:digit:]] '
THEN
SET vNDigits = vNDigits + 1 ;
ELSEIF vChr REGEXP ' [[:punct:]] '
THEN
SET vNPunct = vNPunct + 1 ;
END IF ;
SET vI = vI + 1 ;
END WHILE ;
SELECT
CHAR_LENGTH ( vPassword ) > = length
AND vNAlpha > = nAlpha
AND vNUpper > = nUpper
AND vNDigits > = nDigits
AND vNPunct > = nPunct
INTO vPasswordOk
FROM userPassword LIMIT 1 ;
IF NOT vPasswordOk THEN
SIGNAL SQLSTATE ' 45000 '
SET MESSAGE_TEXT = ' Password does not meet requirements ' ;
END IF ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `userLogin` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` userLogin ` ( vUserName VARCHAR ( 255 ) , vPassword VARCHAR ( 255 ) )
READS SQL DATA
BEGIN
/* *
* Logs in using the user credentials .
*
* @ param vUserName The user name
* @ param vPassword The user password
* /
DECLARE vAuthIsOk BOOLEAN DEFAULT FALSE ;
SELECT COUNT ( * ) = 1 INTO vAuthIsOk FROM user
WHERE name = vUserName
AND password = MD5 ( vPassword )
AND active ;
IF vAuthIsOk
THEN
CALL userLoginWithName ( vUserName ) ;
ELSE
CALL util . throw ( ' INVALID_CREDENTIALS ' ) ;
END IF ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `userLoginWithName` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` userLoginWithName ` ( vUserName VARCHAR ( 255 ) )
READS SQL DATA
BEGIN
/* *
* Logs in using only the user name . This procedure is
* intended to be executed by users with a high level
* of privileges so that normal users should not have
* execute permissions on it
*
* @ param vUserName The user name
* /
DECLARE vUserId INT DEFAULT NULL ;
DECLARE vKey VARCHAR ( 255 ) ;
SELECT id INTO vUserId FROM user
WHERE name = vUserName ;
SELECT loginKey INTO vKey FROM userConfig ;
SET @ userId = vUserId ;
SET @ userName = vUserName ;
SET @ userSignature = util . hmacSha2 ( 256 , CONCAT_WS ( ' / ' , vUserId , vUserName ) , vKey ) ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `userLogout` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` userLogout ` ( )
BEGIN
/* *
* Logouts the user .
* /
SET @ userId = NULL ;
SET @ userName = NULL ;
SET @ userSignature = NULL ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
/* !50003 DROP PROCEDURE IF EXISTS `userSetPassword` */ ;
/* !50003 SET @saved_cs_client = @@character_set_client */ ;
/* !50003 SET @saved_cs_results = @@character_set_results */ ;
/* !50003 SET @saved_col_connection = @@collation_connection */ ;
/* !50003 SET character_set_client = utf8 */ ;
/* !50003 SET character_set_results = utf8 */ ;
/* !50003 SET collation_connection = utf8_general_ci */ ;
/* !50003 SET @saved_sql_mode = @@sql_mode */ ;
/* !50003 SET sql_mode = 'NO_ENGINE_SUBSTITUTION' */ ;
DELIMITER ; ;
CREATE DEFINER = ` root ` @ ` % ` PROCEDURE ` userSetPassword ` ( vUserName VARCHAR ( 255 ) , vPassword VARCHAR ( 255 ) )
BEGIN
/* *
* Cambia la contraseña del usuario pasado como parámetro .
* Solo los administradores deberian de tener privilegios de
* ejecución sobre el procedimiento ya que no solicita la
* contraseña actual del usuario .
*
* @ param vUserName Nombre de usuario
* @ param vPassword Nueva contraseña
* /
CALL userCheckPassword ( vPassword ) ;
UPDATE user SET
password = MD5 ( vPassword ) ,
recoverPass = FALSE
WHERE ` name ` = vUserName ;
END ; ;
DELIMITER ;
/* !50003 SET sql_mode = @saved_sql_mode */ ;
/* !50003 SET character_set_client = @saved_cs_client */ ;
/* !50003 SET character_set_results = @saved_cs_results */ ;
/* !50003 SET collation_connection = @saved_col_connection */ ;
--
-- Final view structure for view `accountDovecot`
--
/* !50001 DROP VIEW IF EXISTS `accountDovecot` */ ;
/* !50001 SET @saved_cs_client = @@character_set_client */ ;
/* !50001 SET @saved_cs_results = @@character_set_results */ ;
/* !50001 SET @saved_col_connection = @@collation_connection */ ;
/* !50001 SET character_set_client = utf8 */ ;
/* !50001 SET character_set_results = utf8 */ ;
/* !50001 SET collation_connection = utf8_general_ci */ ;
/* !50001 CREATE ALGORITHM=UNDEFINED */
/* !50013 DEFINER=`root`@`%` SQL SECURITY DEFINER */
/* !50001 VIEW `accountDovecot` AS select `u`.`name` AS `name`,`u`.`password` AS `password` from (`user` `u` join `account` `a` on((`a`.`id` = `u`.`id`))) where `u`.`active` */ ;
/* !50001 SET character_set_client = @saved_cs_client */ ;
/* !50001 SET character_set_results = @saved_cs_results */ ;
/* !50001 SET collation_connection = @saved_col_connection */ ;
--
-- Final view structure for view `accountPam`
--
/* !50001 DROP VIEW IF EXISTS `accountPam` */ ;
/* !50001 SET @saved_cs_client = @@character_set_client */ ;
/* !50001 SET @saved_cs_results = @@character_set_results */ ;
/* !50001 SET @saved_col_connection = @@collation_connection */ ;
/* !50001 SET character_set_client = utf8 */ ;
/* !50001 SET character_set_results = utf8 */ ;
/* !50001 SET collation_connection = utf8_general_ci */ ;
/* !50001 CREATE ALGORITHM=UNDEFINED */
/* !50013 DEFINER=`root`@`%` SQL SECURITY DEFINER */
/* !50001 VIEW `accountPam` AS select `u`.`name` AS `name`,`u`.`password` AS `password` from (`user` `u` join `account` `a` on((`u`.`id` = `a`.`id`))) where (`u`.`active` <> 0) */ ;
/* !50001 SET character_set_client = @saved_cs_client */ ;
/* !50001 SET character_set_results = @saved_cs_results */ ;
/* !50001 SET collation_connection = @saved_col_connection */ ;
--
-- Final view structure for view `userRole`
--
/* !50001 DROP VIEW IF EXISTS `userRole` */ ;
/* !50001 SET @saved_cs_client = @@character_set_client */ ;
/* !50001 SET @saved_cs_results = @@character_set_results */ ;
/* !50001 SET @saved_col_connection = @@collation_connection */ ;
/* !50001 SET character_set_client = utf8 */ ;
/* !50001 SET character_set_results = utf8 */ ;
/* !50001 SET collation_connection = utf8_general_ci */ ;
/* !50001 CREATE ALGORITHM=UNDEFINED */
/* !50013 DEFINER=`root`@`%` SQL SECURITY DEFINER */
/* !50001 VIEW `userRole` AS select `r`.`inheritsFrom` AS `id` from (`roleRole` `r` join `user` `u` on((`u`.`role` = `r`.`role`))) where (`u`.`id` = `USERGETID`()) */ ;
/* !50001 SET character_set_client = @saved_cs_client */ ;
/* !50001 SET character_set_results = @saved_cs_results */ ;
/* !50001 SET collation_connection = @saved_col_connection */ ;
--
-- Final view structure for view `userView`
--
/* !50001 DROP VIEW IF EXISTS `userView` */ ;
/* !50001 SET @saved_cs_client = @@character_set_client */ ;
/* !50001 SET @saved_cs_results = @@character_set_results */ ;
/* !50001 SET @saved_col_connection = @@collation_connection */ ;
/* !50001 SET character_set_client = utf8 */ ;
/* !50001 SET character_set_results = utf8 */ ;
/* !50001 SET collation_connection = utf8_general_ci */ ;
/* !50001 CREATE ALGORITHM=UNDEFINED */
/* !50013 DEFINER=`root`@`%` SQL SECURITY DEFINER */
/* !50001 VIEW `userView` AS select `u`.`id` AS `id`,`u`.`name` AS `name`,`u`.`active` AS `active`,`u`.`email` AS `email`,`u`.`nickname` AS `nickname`,`u`.`lang` AS `lang`,`u`.`role` AS `role`,`u`.`recoverPass` AS `recoverPass` from `user` `u` where (`u`.`name` = `account`.`userGetName`()) */
/* !50002 WITH CASCADED CHECK OPTION */ ;
/* !50001 SET character_set_client = @saved_cs_client */ ;
/* !50001 SET character_set_results = @saved_cs_results */ ;
/* !50001 SET collation_connection = @saved_col_connection */ ;
/* !40103 SET TIME_ZONE=@OLD_TIME_ZONE */ ;
/* !40101 SET SQL_MODE=@OLD_SQL_MODE */ ;
/* !40014 SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS */ ;
/* !40014 SET UNIQUE_CHECKS=@OLD_UNIQUE_CHECKS */ ;
/* !40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */ ;
/* !40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */ ;
/* !40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */ ;
/* !40111 SET SQL_NOTES=@OLD_SQL_NOTES */ ;
2018-01-24 07:06:49 +00:00
-- Dump completed on 2018-01-23 12:30:01