summaryrefslogtreecommitdiffstats
path: root/dozentenmodulserver/setup/sat-01-schema.sql
blob: 2f60b22774d83ee619946e8ac2741c40e9212f00 (plain) (blame)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO";
SET time_zone = "+00:00";

/*!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 */;

CREATE DATABASE IF NOT EXISTS `sat` DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
USE `sat`;

CREATE TABLE IF NOT EXISTS `imagebase` (
  `imagebaseid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `latestversionid` char(36) CHARACTER SET ascii COLLATE ascii_bin DEFAULT NULL,
  `displayname` varchar(100) NOT NULL,
  `description` TEXT NULL DEFAULT NULL,
  `osid` INT NULL DEFAULT NULL,
  `virtid` VARCHAR(10) NULL DEFAULT NULL,
  `createtime` bigint(20) NOT NULL,
  `updatetime` bigint(20) NOT NULL,
  `ownerid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `updaterid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `sharemode` enum('LOCAL','PUBLISH','DOWNLOAD', 'FROZEN') NOT NULL,
  `istemplate` tinyint(1) NOT NULL,
  `canlinkdefault` tinyint(1) NOT NULL,
  `candownloaddefault` tinyint(1) NOT NULL,
  `caneditdefault` tinyint(1) NOT NULL,
  `canadmindefault` tinyint(1) NOT NULL,
  PRIMARY KEY (`imagebaseid`),
  KEY `owner` (`ownerid`),
  KEY `fk_imagebase_1_idx` (`osid`),
  KEY `fk_imagebase_owner_idx` (`updaterid`),
  KEY `fk_imagebase_1_idx1` (`virtid`),
  KEY `latestversion_idx` (`latestversionid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `imagetag` (
  `imagebaseid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `tagname` CHAR(32) NOT NULL,
  PRIMARY KEY (`imagebaseid`,`tagname`),
  KEY `tag_image` (`tagname`,`imagebaseid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `imageblock` (
  `imageversionid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `startbyte` bigint(20) NOT NULL,
  `blocksize` int(11) NOT NULL,
  `blocksha1` binary(20) DEFAULT NULL,
  `ismissing` tinyint(1) NOT NULL COMMENT 'true if this block is missing from the file, either because it was not transferred to the server yet, or because it failed an integrity check.',
  PRIMARY KEY (`imageversionid`,`startbyte`,`blocksize`),
  KEY `checksums` (`blocksha1`,`blocksize`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `imagepermission` (
  `imagebaseid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `userid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `canlink` tinyint(1) NOT NULL,
  `candownload` tinyint(1) NOT NULL,
  `canedit` tinyint(1) NOT NULL,
  `canadmin` tinyint(1) NOT NULL,
  PRIMARY KEY (`imagebaseid`,`userid`),
  KEY `fk_imagepermission_2_idx` (`userid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `imageversion` (
  `imageversionid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `imagebaseid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `createtime` bigint(20) NOT NULL,
  `expiretime` bigint(20) NOT NULL,
  `filesize` bigint(20) NOT NULL,
  `filepath` varchar(200) NOT NULL,
  `uploaderid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `isrestricted` tinyint(1) NOT NULL,
  `isvalid` tinyint(1) NOT NULL,
  `isprocessed` tinyint(1) NOT NULL,
  `mastersha1` binary(20) DEFAULT NULL,
  `virtualizerconfig` blob NULL DEFAULT NULL COMMENT 'Specific configuration of the virtualizer for this image. For vmware, this is basically a dump of the *.vmx.',
  `deletestate` ENUM( 'KEEP', 'SHOULD_DELETE', 'WANT_DELETE' ) CHARACTER SET ascii COLLATE ascii_bin NOT NULL DEFAULT 'KEEP',
  PRIMARY KEY (`imageversionid`),
  KEY `version_access` (`imagebaseid`,`isvalid`,`createtime`),
  KEY `fk_imageversion_2_idx` (`uploaderid`),
  KEY `expire_index` (`expiretime`),
  KEY `deletestate` (`deletestate`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `imageversion_x_software` (
  `imageversionid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `softwareid` int(11) NOT NULL,
  PRIMARY KEY (`imageversionid`,`softwareid`),
  KEY `fk_imageversion_x_software_2_idx` (`softwareid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `software_x_tag` (
  `softwareid` int(11) NOT NULL,
  `tagname` CHAR(32) NOT NULL,
  PRIMARY KEY (`softwareid`,`tagname`),
  KEY `fk_software_x_tag_2_idx` (`tagname`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `lecture` (
  `lectureid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `displayname` varchar(100) NOT NULL,
  `description` text NOT NULL,
  `imageversionid` char(36) CHARACTER SET ascii COLLATE ascii_bin NULL COMMENT 'We reference a specific image version here, not the base image.\nOn update of an image, we update the lecture table for all matching lectures that used the current image version.\nThis way, a tutor can explicitly switch back to an older version of an image.',
  `autoupdate` tinyint(1) UNSIGNED NOT NULL DEFAULT '1',
  `isenabled` tinyint(1) UNSIGNED NOT NULL DEFAULT '1',
  `isprivate` tinyint(1) UNSIGNED NOT NULL DEFAULT '0' COMMENT 'Only users from the lectureuser table can start this lecture',
  `starttime` bigint(20) NOT NULL,
  `endtime` bigint(20) NOT NULL,
  `lastused` bigint(20) NOT NULL DEFAULT '0',
  `usecount` int(11) NOT NULL DEFAULT '0',
  `createtime` bigint(20) NOT NULL,
  `updatetime` bigint(20) NOT NULL,
  `ownerid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `updaterid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `runscript` text DEFAULT NULL,
  `nics` VARCHAR(200) CHARACTER SET ascii COLLATE ascii_bin NULL COMMENT 'Freeform text field for future extendability. Format is specified at application layer.',
  `netrules` text DEFAULT NULL COMMENT 'user defined firewall rules, applied at the linux base system.',
  `isexam` tinyint(1) NOT NULL,
  `iswhitelistonly` tinyint(1) NOT NULL DEFAULT '0',
  `hasinternetaccess` tinyint(1) NOT NULL,
  `hasusbaccess` tinyint(1) NOT NULL,
  `caneditdefault` tinyint(1) NOT NULL,
  `canadmindefault` tinyint(1) NOT NULL,
  PRIMARY KEY (`lectureid`),
  KEY `fk_lecture_1_idx` (`imageversionid`),
  KEY `fk_lecture_2_idx` (`ownerid`),
  KEY `fk_lecture_3_idx` (`updaterid`),
  KEY `list_lookup` (`isenabled`,`isexam`,`isprivate`,`endtime`,`starttime`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `lecturepermission` (
  `lectureid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `userid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `canedit` tinyint(1) NOT NULL,
  `canadmin` tinyint(1) NOT NULL,
  PRIMARY KEY (`lectureid`,`userid`),
  KEY `fk_lecturepermission_2_idx` (`userid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `operatingsystem` (
  `osid` int(11) NOT NULL COMMENT 'Defined on the master server, so no auto_increment!',
  `displayname` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL,
  `architecture` varchar(14) COLLATE utf8mb4_unicode_ci NOT NULL,
  `maxmem` int(11) NOT NULL,
  `maxcpu` int(11) NOT NULL,
  PRIMARY KEY (`osid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `organization` (
  `organizationid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `displayname` varchar(255) NOT NULL,
  `canlogin` tinyint(1) NOT NULL DEFAULT '0',
  PRIMARY KEY (`organizationid`),
  KEY `loginkey` (`canlogin`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `os_x_virt` (
  `osid` int(11) NOT NULL,
  `virtid` varchar(10) NOT NULL,
  `virtoskeyword` varchar(30) NOT NULL,
  PRIMARY KEY (`osid`,`virtid`),
  KEY `fk_os_x_virt_2_idx` (`virtid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `software` (
  `softwareid` int(11) NOT NULL AUTO_INCREMENT COMMENT 'This ID is used internally only, it never leaves the satellite.',
  `softwarestring` varchar(120) NOT NULL,
  `isrestricted` TINYINT(1) NOT NULL,
  `isrestrictedoverride` TINYINT(1) NULL,
  PRIMARY KEY (`softwareid`),
  UNIQUE KEY `softwarestring_UNIQUE` (`softwarestring`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `user` (
  `userid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `firstname` varchar(50) NOT NULL,
  `lastname` varchar(50) NOT NULL,
  `email` varchar(50) NOT NULL,
  `organizationid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `lastlogin` bigint(20) DEFAULT NULL,
  `canlogin` tinyint(1) NOT NULL DEFAULT '0',
  `issuperuser` tinyint(1) NOT NULL DEFAULT '0',
  `emailnotifications` tinyint(1) NOT NULL DEFAULT '1',
  PRIMARY KEY (`userid`),
  KEY `fk_user_1_idx` (`organizationid`),
  KEY `mail_idx` (`email`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `virtualizer` (
  `virtid` varchar(10) NOT NULL,
  `virtname` varchar(20) NOT NULL,
  PRIMARY KEY (`virtid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `lectureuser` (
  `lectureid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `userlogin` VARCHAR(45) NOT NULL,
  PRIMARY KEY (`lectureid`, `userlogin`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;

CREATE TABLE IF NOT EXISTS `configuration` (
  `parameter` varchar(100) CHARACTER SET ascii NOT NULL,
  `value` blob NOT NULL,
  PRIMARY KEY (`parameter`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;

CREATE TABLE IF NOT EXISTS `mailqueue` (
  `mailid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `userid` char(36) CHARACTER SET ascii COLLATE ascii_bin NOT NULL,
  `message` text NOT NULL,
  `failcount` int(11) NOT NULL DEFAULT '0',
  `dateline` bigint(20) NOT NULL,
  PRIMARY KEY (`mailid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;

ALTER TABLE `lectureuser`
  ADD CONSTRAINT `fk_lectureuser_1` FOREIGN KEY (`lectureid`) REFERENCES `sat`.`lecture` (`lectureid`) ON DELETE CASCADE ON UPDATE CASCADE;

ALTER TABLE `imagebase`
  ADD CONSTRAINT `fk_imagebase_os` FOREIGN KEY (`osid`) REFERENCES `operatingsystem` (`osid`),
  ADD CONSTRAINT `fk_imagebase_owner` FOREIGN KEY (`ownerid`) REFERENCES `user` (`userid`) ON UPDATE CASCADE,
  ADD CONSTRAINT `fk_imagebase_updater` FOREIGN KEY (`updaterid`) REFERENCES `user` (`userid`) ON UPDATE CASCADE,
  ADD CONSTRAINT `fk_imagebase_1` FOREIGN KEY (`virtid`) REFERENCES `virtualizer` (`virtid`) ON UPDATE CASCADE,
  ADD CONSTRAINT `latestversion` FOREIGN KEY (`latestversionid`) REFERENCES `imageversion` (`imageversionid`) ON UPDATE CASCADE;

ALTER TABLE `imagetag`
  ADD CONSTRAINT `fk_imagetag_1` FOREIGN KEY (`imagebaseid`) REFERENCES `imagebase` (`imagebaseid`) ON UPDATE CASCADE ON DELETE CASCADE;

ALTER TABLE `imageblock`
  ADD CONSTRAINT `fk_imageblocksha1_1` FOREIGN KEY (`imageversionid`) REFERENCES `imageversion` (`imageversionid`) ON UPDATE CASCADE ON DELETE CASCADE;

ALTER TABLE `imagepermission`
  ADD CONSTRAINT `fk_imagepermission_1` FOREIGN KEY (`imagebaseid`) REFERENCES `imagebase` (`imagebaseid`) ON UPDATE CASCADE ON DELETE CASCADE,
  ADD CONSTRAINT `fk_imagepermission_2` FOREIGN KEY (`userid`) REFERENCES `user` (`userid`) ON UPDATE CASCADE ON DELETE CASCADE;

ALTER TABLE `imageversion`
  ADD CONSTRAINT `fk_imageversion_base` FOREIGN KEY (`imagebaseid`) REFERENCES `imagebase` (`imagebaseid`) ON UPDATE CASCADE,
  ADD CONSTRAINT `fk_imageversion_creator` FOREIGN KEY (`uploaderid`) REFERENCES `user` (`userid`) ON UPDATE CASCADE;

ALTER TABLE `imageversion_x_software`
  ADD CONSTRAINT `fk_imageversion_x_software_1` FOREIGN KEY (`imageversionid`) REFERENCES `imageversion` (`imageversionid`) ON UPDATE CASCADE ON DELETE CASCADE,
  ADD CONSTRAINT `fk_imageversion_x_software_2` FOREIGN KEY (`softwareid`) REFERENCES `software` (`softwareid`) ON UPDATE CASCADE ON DELETE CASCADE;

ALTER TABLE `lecture`
  ADD CONSTRAINT `fk_lecture_image` FOREIGN KEY (`imageversionid`) REFERENCES `imageversion` (`imageversionid`) ON UPDATE CASCADE,
  ADD CONSTRAINT `fk_lecture_owner` FOREIGN KEY (`ownerid`) REFERENCES `user` (`userid`) ON UPDATE CASCADE,
  ADD CONSTRAINT `fk_lecture_updater` FOREIGN KEY (`updaterid`) REFERENCES `user` (`userid`) ON UPDATE CASCADE;

ALTER TABLE `lecturepermission`
  ADD CONSTRAINT `fk_lecturepermission_1` FOREIGN KEY (`lectureid`) REFERENCES `lecture` (`lectureid`) ON UPDATE CASCADE ON DELETE CASCADE,
  ADD CONSTRAINT `fk_lecturepermission_2` FOREIGN KEY (`userid`) REFERENCES `user` (`userid`) ON UPDATE CASCADE ON DELETE CASCADE;

ALTER TABLE `os_x_virt`
  ADD CONSTRAINT `fk_os_x_virt_1` FOREIGN KEY (`osid`) REFERENCES `operatingsystem` (`osid`) ON UPDATE CASCADE ON DELETE CASCADE,
  ADD CONSTRAINT `fk_os_x_virt_2` FOREIGN KEY (`virtid`) REFERENCES `virtualizer` (`virtid`) ON UPDATE CASCADE ON DELETE CASCADE;

ALTER TABLE `user`
  ADD CONSTRAINT `fk_user_1` FOREIGN KEY (`organizationid`) REFERENCES `organization` (`organizationid`) ON UPDATE CASCADE;

ALTER TABLE `software_x_tag`
  ADD CONSTRAINT `fk_software_x_tag_1` FOREIGN KEY (`softwareid`) REFERENCES `software` (`softwareid`) ON UPDATE CASCADE ON DELETE CASCADE;

/*!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 */;