changes
This commit is contained in:
81
initial-schema.sql
Normal file
81
initial-schema.sql
Normal file
@ -0,0 +1,81 @@
|
||||
CREATE TABLE `issuers` (
|
||||
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
|
||||
`name` varchar(128) NOT NULL,
|
||||
`secret` varchar(128) NOT NULL,
|
||||
`max_expiry` int(10) NOT NULL,
|
||||
CONSTRAINT PRIMARY KEY (`id`),
|
||||
CONSTRAINT UNIQUE KEY `uk_issuers_name` (`name`)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
ALTER TABLE `issuers`
|
||||
MODIFY COLUMN `max_expiry` int(10) unsigned NOT NULL;
|
||||
|
||||
CREATE TABLE `users` (
|
||||
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
|
||||
`login` varchar(64) NOT NULL,
|
||||
`password` varchar(64) NOT NULL,
|
||||
CONSTRAINT PRIMARY KEY (`id`),
|
||||
CONSTRAINT UNIQUE KEY `uk_users_login` (`login`)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
ALTER TABLE `users`
|
||||
ADD COLUMN issuer int(10) unsigned;
|
||||
|
||||
ALTER TABLE `users`
|
||||
MODIFY COLUMN issuer int(10) unsigned NOT NULL;
|
||||
|
||||
ALTER TABLE `users`
|
||||
ADD CONSTRAINT FOREIGN KEY `fk_users_issuer` (`issuer`)
|
||||
REFERENCES `issuers` (`id`);
|
||||
|
||||
ALTER TABLE `users`
|
||||
DROP CONSTRAINT `uk_users_login`;
|
||||
|
||||
ALTER TABLE `users`
|
||||
ADD CONSTRAINT UNIQUE KEY `uk_users_login_issuer` (`login`, `issuer`);
|
||||
|
||||
ALTER TABLE `users`
|
||||
ADD COLUMN expiry int(10) unsigned;
|
||||
|
||||
ALTER TABLE `users`
|
||||
MODIFY COLUMN expiry int(10) unsigned NOT NULL;
|
||||
|
||||
CREATE TABLE `claims` (
|
||||
`id` int(10) unsigned NOT NULL AUTO_INCREMENT,
|
||||
`key` varchar(64) NOT NULL,
|
||||
`value` varchar(1024) NOT NULL,
|
||||
CONSTRAINT PRIMARY KEY (`id`),
|
||||
CONSTRAINT UNIQUE KEY `uk_claims_key_value` (`key`, `value`)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
CREATE TABLE `user_claims_mapping` (
|
||||
`user` int(10) unsigned NOT NULL,
|
||||
`claim` int(10) unsigned NOT NULL,
|
||||
CONSTRAINT UNIQUE KEY `uk_user_claims_mapping` (`user`, `claim` ),
|
||||
CONSTRAINT FOREIGN KEY `fk_user_claims_mapping_user` (`user`)
|
||||
REFERENCES `users`(`id`),
|
||||
CONSTRAINT FOREIGN KEY `fk_user_claims_mapping_claim` (`claim`)
|
||||
REFERENCES `claims`(`id`)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
CREATE OR REPLACE VIEW claims_for_user AS
|
||||
SELECT u.id AS user,
|
||||
c.`key` AS `key`,
|
||||
c.`value` AS `value`
|
||||
FROM users u,
|
||||
claims c,
|
||||
user_claims_mapping m
|
||||
WHERE m.user = u.id AND
|
||||
m.claim = c.id;
|
||||
|
||||
CREATE OR REPLACE VIEW user_and_issuer AS
|
||||
SELECT u.login AS login,
|
||||
u.password AS password,
|
||||
u.id AS id,
|
||||
i.name AS issuer,
|
||||
i.secret AS secret,
|
||||
least(u.expiry, i.max_expiry) AS expiry
|
||||
FROM users u,
|
||||
issuers i
|
||||
WHERE u.issuer = i.id;
|
||||
|
Reference in New Issue
Block a user