|
| 1 | +/* community edition */ |
| 2 | + |
| 3 | +-- permission records space and document level privelges, making existing labelrole table obsolete |
| 4 | +-- who column can be user or role |
| 5 | +-- whoid column contains eitehr user or role ID |
| 6 | +-- action column records permission type (view, edit, delete...) |
| 7 | +-- scope column details if action applies to object or table |
| 8 | +-- location column details name of table |
| 9 | +-- refid column details ID of item that the action applies to (only if scope=object) |
| 10 | +DROP TABLE IF EXISTS `permission`; |
| 11 | + |
| 12 | +CREATE TABLE IF NOT EXISTS `permission` ( |
| 13 | + `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, |
| 14 | + `orgid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 15 | + `who` VARCHAR(30) NOT NULL, |
| 16 | + `whoid` CHAR(16) DEFAULT '' NOT NULL COLLATE utf8_bin, |
| 17 | + `action` VARCHAR(30) NOT NULL, |
| 18 | + `scope` VARCHAR(30) NOT NULL, |
| 19 | + `location` VARCHAR(100) NOT NULL, |
| 20 | + `refid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 21 | + `created` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 22 | + UNIQUE INDEX `idx_permission_id` (`id` ASC), |
| 23 | + INDEX `idx_permission_orgid` (`orgid` ASC)) |
| 24 | +DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci |
| 25 | +ENGINE = MyISAM; |
| 26 | + |
| 27 | +CREATE INDEX idx_permission_1 ON permission(orgid,who,whoid,location); |
| 28 | +CREATE INDEX idx_permission_2 ON permission(orgid,who,whoid,location,action); |
| 29 | +CREATE INDEX idx_permission_3 ON permission(orgid,location,refid); |
| 30 | +CREATE INDEX idx_permission_4 ON permission(orgid,who,location,action); |
| 31 | + |
| 32 | +-- category represents "folder/label/category" assignment to document (1:M) |
| 33 | +DROP TABLE IF EXISTS `category`; |
| 34 | + |
| 35 | +CREATE TABLE IF NOT EXISTS `category` ( |
| 36 | + `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, |
| 37 | + `refid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 38 | + `orgid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 39 | + `labelid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 40 | + `category` VARCHAR(30) NOT NULL, |
| 41 | + `created` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 42 | + `revised` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 43 | + UNIQUE INDEX `idx_category_id` (`id` ASC), |
| 44 | + INDEX `idx_category_refid` (`refid` ASC), |
| 45 | + INDEX `idx_category_orgid` (`orgid` ASC)) |
| 46 | +DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci |
| 47 | +ENGINE = MyISAM; |
| 48 | + |
| 49 | +CREATE INDEX idx_category_1 ON category(orgid,labelid); |
| 50 | + |
| 51 | +-- category member records who can see a category and the documents within |
| 52 | +DROP TABLE IF EXISTS `categorymember`; |
| 53 | + |
| 54 | +CREATE TABLE IF NOT EXISTS `categorymember` ( |
| 55 | + `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, |
| 56 | + `refid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 57 | + `orgid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 58 | + `labelid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 59 | + `categoryid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 60 | + `documentid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 61 | + `created` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 62 | + `revised` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 63 | + UNIQUE INDEX `idx_categorymember_id` (`id` ASC), |
| 64 | + INDEX `idx_category_documentid` (`documentid`)) |
| 65 | + DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci |
| 66 | +ENGINE = MyISAM; |
| 67 | + |
| 68 | +CREATE INDEX idx_categorymember_1 ON categorymember(orgid,documentid); |
| 69 | +CREATE INDEX idx_categorymember_2 ON categorymember(orgid,labelid); |
| 70 | + |
| 71 | +-- rolee represent user groups |
| 72 | +DROP TABLE IF EXISTS `role`; |
| 73 | + |
| 74 | +CREATE TABLE IF NOT EXISTS `role` ( |
| 75 | + `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, |
| 76 | + `refid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 77 | + `orgid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 78 | + `role` VARCHAR(30) NOT NULL, |
| 79 | + `created` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, |
| 80 | + UNIQUE INDEX `idx_category_id` (`id` ASC), |
| 81 | + INDEX `idx_category_refid` (`refid` ASC), |
| 82 | + INDEX `idx_category_orgid` (`orgid` ASC)) |
| 83 | +DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci |
| 84 | +ENGINE = MyISAM; |
| 85 | + |
| 86 | +-- role member records user role membership |
| 87 | +DROP TABLE IF EXISTS `rolemember`; |
| 88 | + |
| 89 | +CREATE TABLE IF NOT EXISTS `rolemember` ( |
| 90 | + `id` INT UNSIGNED NOT NULL AUTO_INCREMENT, |
| 91 | + `orgid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 92 | + `roleid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 93 | + `userid` CHAR(16) NOT NULL COLLATE utf8_bin, |
| 94 | + UNIQUE INDEX `idx_category_id` (`id` ASC)) |
| 95 | +DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci |
| 96 | +ENGINE = MyISAM; |
| 97 | + |
| 98 | +CREATE INDEX idx_rolemember_1 ON rolemember(roleid,userid); |
| 99 | +CREATE INDEX idx_rolemember_2 ON rolemember(orgid,roleid,userid); |
| 100 | + |
| 101 | +-- user account can have global permssion to state if user can see all other users |
| 102 | +-- provides granular control for external users |
| 103 | +ALTER TABLE account ADD COLUMN `users` BOOL NOT NULL DEFAULT 1 AFTER `admin`; |
| 104 | + |
| 105 | +-- migrate space/document permissions |
| 106 | + |
| 107 | +-- space own |
| 108 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 109 | + SELECT orgid, 'user' as who, userid as whois, 'own' as `action`, 'object' as scope, 'space' as location, refid |
| 110 | + FROM label; |
| 111 | + |
| 112 | +-- space manage (same as owner) |
| 113 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 114 | + SELECT orgid, 'user' as who, userid as whois, 'manage' as `action`, 'object' as scope, 'space' as location, refid |
| 115 | + FROM label; |
| 116 | + |
| 117 | +-- view space |
| 118 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 119 | + SELECT orgid, 'user' as who, userid as whois, 'view' as `action`, 'object' as scope, 'space' as location, labelid as refid |
| 120 | + FROM labelrole WHERE canview=1; |
| 121 | + |
| 122 | +-- edit space => add/edit/delete/move/copy/template documents |
| 123 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 124 | + SELECT orgid, 'user' as who, userid as whois, 'doc-add' as `action`, 'object' as scope, 'space' as location, labelid as refid |
| 125 | + FROM labelrole WHERE canedit=1; |
| 126 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 127 | + SELECT orgid, 'user' as who, userid as whois, 'doc-edit' as `action`, 'object' as scope, 'space' as location, labelid as refid |
| 128 | + FROM labelrole WHERE canedit=1; |
| 129 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 130 | + SELECT orgid, 'user' as who, userid as whois, 'doc-delete' as `action`, 'object' as scope, 'space' as location, labelid as refid |
| 131 | + FROM labelrole WHERE canedit=1; |
| 132 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 133 | + SELECT orgid, 'user' as who, userid as whois, 'doc-move' as `action`, 'object' as scope, 'space' as location, labelid as refid |
| 134 | + FROM labelrole WHERE canedit=1; |
| 135 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 136 | + SELECT orgid, 'user' as who, userid as whois, 'doc-copy' as `action`, 'object' as scope, 'space' as location, labelid as refid |
| 137 | + FROM labelrole WHERE canedit=1; |
| 138 | +INSERT INTO permission (orgid, who, whoid, `action`, scope, location, refid) |
| 139 | + SELECT orgid, 'user' as who, userid as whois, 'doc-template' as `action`, 'object' as scope, 'space' as location, labelid as refid |
| 140 | + FROM labelrole WHERE canedit=1; |
| 141 | + |
| 142 | +-- everyone users ID changed to 0 |
| 143 | +UPDATE permission SET whoid='0' WHERE whoid=''; |
0 commit comments