aur-schema.sql 11.7 KB
Newer Older
eric's avatar
eric committed
1
-- The MySQL database layout for the AUR.  Certain data
2
-- is also included such as AccountTypes, etc.
eric's avatar
eric committed
3
--
4
DROP DATABASE IF EXISTS AUR;
Loui Chang's avatar
Loui Chang committed
5
CREATE DATABASE AUR DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci;
6
USE AUR;
eric's avatar
eric committed
7
8
9
10

-- Define the Account Types for the AUR.
--
CREATE TABLE AccountTypes (
11
	ID TINYINT UNSIGNED NOT NULL AUTO_INCREMENT,
12
	AccountType VARCHAR(32) NOT NULL DEFAULT '',
eric's avatar
eric committed
13
	PRIMARY KEY (ID)
14
) ENGINE = InnoDB;
15
16
17
INSERT INTO AccountTypes (ID, AccountType) VALUES (1, 'User');
INSERT INTO AccountTypes (ID, AccountType) VALUES (2, 'Trusted User');
INSERT INTO AccountTypes (ID, AccountType) VALUES (3, 'Developer');
18
INSERT INTO AccountTypes (ID, AccountType) VALUES (4, 'Trusted User & Developer');
eric's avatar
eric committed
19
20
21
22
23


-- User information for each user regardless of type.
--
CREATE TABLE Users (
24
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
eric's avatar
eric committed
25
	AccountTypeID TINYINT UNSIGNED NOT NULL DEFAULT 1,
26
	Suspended TINYINT UNSIGNED NOT NULL DEFAULT 0,
27
28
	Username VARCHAR(32) NOT NULL,
	Email VARCHAR(64) NOT NULL,
eric's avatar
eric committed
29
	Passwd CHAR(32) NOT NULL,
Denis's avatar
Denis committed
30
	Salt CHAR(32) NOT NULL DEFAULT '',
31
	ResetKey CHAR(32) NOT NULL DEFAULT '',
32
33
34
	RealName VARCHAR(64) NOT NULL DEFAULT '',
	LangPreference VARCHAR(5) NOT NULL DEFAULT 'en',
	IRCNick VARCHAR(32) NOT NULL DEFAULT '',
35
	PGPKey VARCHAR(40) NULL DEFAULT NULL,
36
	LastLogin BIGINT UNSIGNED NOT NULL DEFAULT 0,
Lukas Fleischer's avatar
Lukas Fleischer committed
37
	LastLoginIPAddress INTEGER UNSIGNED NOT NULL DEFAULT 0,
38
	InactivityTS BIGINT UNSIGNED NOT NULL DEFAULT 0,
39
	RegistrationTS TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
eric's avatar
eric committed
40
	PRIMARY KEY (ID),
eric's avatar
eric committed
41
	UNIQUE (Username),
42
43
44
	UNIQUE (Email),
	INDEX (AccountTypeID),
	FOREIGN KEY (AccountTypeID) REFERENCES AccountTypes(ID) ON DELETE NO ACTION
45
) ENGINE = InnoDB;
eric's avatar
eric committed
46
-- A default developer account for testing purposes
47
INSERT INTO Users (ID, AccountTypeID, Username, Email, Passwd) VALUES (
48
	1, 3, 'dev', 'dev@localhost', MD5('dev'));
eric's avatar
eric committed
49
INSERT INTO Users (ID, AccountTypeID, Username, Email, Passwd) VALUES (
50
	2, 2, 'tu', 'tu@localhost', MD5('tu'));
eric's avatar
eric committed
51
INSERT INTO Users (ID, AccountTypeID, Username, Email, Passwd) VALUES (
52
	3, 1, 'user', 'user@localhost', MD5('user'));
eric's avatar
eric committed
53
54


55
56
57
58
59
60
61
62
63
64
65
-- SSH public keys used for the aurweb SSH/Git interface.
--
CREATE TABLE SSHPubKeys (
	UserID INTEGER UNSIGNED NOT NULL,
	Fingerprint VARCHAR(44) NOT NULL,
	PubKey VARCHAR(4096) NOT NULL,
	PRIMARY KEY (Fingerprint),
	FOREIGN KEY (UserID) REFERENCES Users(ID) ON DELETE CASCADE
) ENGINE = InnoDB;


eric's avatar
eric committed
66
67
68
-- Track Users logging in/out of AUR web site.
--
CREATE TABLE Sessions (
69
	UsersID INTEGER UNSIGNED NOT NULL,
eric's avatar
eric committed
70
	SessionID CHAR(32) NOT NULL,
71
	LastUpdateTS BIGINT UNSIGNED NOT NULL,
72
	FOREIGN KEY (UsersID) REFERENCES Users(ID) ON DELETE CASCADE,
eric's avatar
eric committed
73
	UNIQUE (SessionID)
74
) ENGINE = InnoDB;
eric's avatar
eric committed
75
76


77
-- Information on package bases
eric's avatar
eric committed
78
--
79
CREATE TABLE PackageBases (
80
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
81
	Name VARCHAR(255) NOT NULL,
82
	NumVotes INTEGER UNSIGNED NOT NULL DEFAULT 0,
83
	Popularity DECIMAL(10,6) UNSIGNED NOT NULL DEFAULT 0,
84
	OutOfDateTS BIGINT UNSIGNED NULL DEFAULT NULL,
85
	FlaggerComment VARCHAR(255) NOT NULL,
86
	SubmittedTS BIGINT UNSIGNED NOT NULL,
simo's avatar
simo committed
87
	ModifiedTS BIGINT UNSIGNED NOT NULL,
88
	FlaggerUID INTEGER UNSIGNED NULL DEFAULT NULL,       -- who flagged the package out-of-date?
89
90
	SubmitterUID INTEGER UNSIGNED NULL DEFAULT NULL,     -- who submitted it?
	MaintainerUID INTEGER UNSIGNED NULL DEFAULT NULL,    -- User
91
	PackagerUID INTEGER UNSIGNED NULL DEFAULT NULL,      -- Last packager
eric's avatar
eric committed
92
	PRIMARY KEY (ID),
93
	UNIQUE (Name),
94
	INDEX (NumVotes),
95
96
	INDEX (SubmitterUID),
	INDEX (MaintainerUID),
97
	INDEX (PackagerUID),
98
	FOREIGN KEY (FlaggerUID) REFERENCES Users(ID) ON DELETE SET NULL,
99
100
	-- deleting a user will cause packages to be orphaned, not deleted
	FOREIGN KEY (SubmitterUID) REFERENCES Users(ID) ON DELETE SET NULL,
101
102
	FOREIGN KEY (MaintainerUID) REFERENCES Users(ID) ON DELETE SET NULL,
	FOREIGN KEY (PackagerUID) REFERENCES Users(ID) ON DELETE SET NULL
103
) ENGINE = InnoDB;
eric's avatar
eric committed
104
105


106
107
108
109
110
111
112
113
114
115
-- Keywords of package bases
--
CREATE TABLE PackageKeywords (
	PackageBaseID INTEGER UNSIGNED NOT NULL,
	Keyword VARCHAR(255) NOT NULL DEFAULT '',
	PRIMARY KEY (PackageBaseID, Keyword),
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE
) ENGINE = InnoDB;


116
117
118
119
120
-- Information about the actual packages
--
CREATE TABLE Packages (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
	PackageBaseID INTEGER UNSIGNED NOT NULL,
121
122
	Name VARCHAR(255) NOT NULL,
	Version VARCHAR(255) NOT NULL DEFAULT '',
123
124
	Description VARCHAR(255) NULL DEFAULT NULL,
	URL VARCHAR(255) NULL DEFAULT NULL,
125
126
127
	PRIMARY KEY (ID),
	UNIQUE (Name),
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE
128
129
130
131
132
133
134
) ENGINE = InnoDB;


-- Information about licenses
--
CREATE TABLE Licenses (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
135
	Name VARCHAR(255) NOT NULL,
136
137
138
139
140
141
142
143
144
145
146
147
148
	PRIMARY KEY (ID),
	UNIQUE (Name)
) ENGINE = InnoDB;


-- Information about package-license-relations
--
CREATE TABLE PackageLicenses (
	PackageID INTEGER UNSIGNED NOT NULL,
	LicenseID INTEGER UNSIGNED NOT NULL,
	PRIMARY KEY (PackageID, LicenseID),
	FOREIGN KEY (PackageID) REFERENCES Packages(ID) ON DELETE CASCADE,
	FOREIGN KEY (LicenseID) REFERENCES Licenses(ID) ON DELETE CASCADE
149
150
151
) ENGINE = InnoDB;


152
153
154
155
-- Information about groups
--
CREATE TABLE Groups (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
156
	Name VARCHAR(255) NOT NULL,
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
	PRIMARY KEY (ID),
	UNIQUE (Name)
) ENGINE = InnoDB;


-- Information about package-group-relations
--
CREATE TABLE PackageGroups (
	PackageID INTEGER UNSIGNED NOT NULL,
	GroupID INTEGER UNSIGNED NOT NULL,
	PRIMARY KEY (PackageID, GroupID),
	FOREIGN KEY (PackageID) REFERENCES Packages(ID) ON DELETE CASCADE,
	FOREIGN KEY (GroupID) REFERENCES Groups(ID) ON DELETE CASCADE
) ENGINE = InnoDB;


173
174
175
176
177
178
179
180
181
182
183
184
185
-- Define the package dependency types
--
CREATE TABLE DependencyTypes (
	ID TINYINT UNSIGNED NOT NULL AUTO_INCREMENT,
	Name VARCHAR(32) NOT NULL DEFAULT '',
	PRIMARY KEY (ID)
) ENGINE = InnoDB;
INSERT INTO DependencyTypes VALUES (1, 'depends');
INSERT INTO DependencyTypes VALUES (2, 'makedepends');
INSERT INTO DependencyTypes VALUES (3, 'checkdepends');
INSERT INTO DependencyTypes VALUES (4, 'optdepends');


186
187
188
189
-- Track which dependencies a package has
--
CREATE TABLE PackageDepends (
	PackageID INTEGER UNSIGNED NOT NULL,
190
	DepTypeID TINYINT UNSIGNED NOT NULL,
191
	DepName VARCHAR(255) NOT NULL,
192
	DepCondition VARCHAR(255),
193
	DepArch VARCHAR(255) NULL DEFAULT NULL,
194
	INDEX (PackageID),
195
	INDEX (DepName),
196
197
	FOREIGN KEY (PackageID) REFERENCES Packages(ID) ON DELETE CASCADE,
	FOREIGN KEY (DepTypeID) REFERENCES DependencyTypes(ID) ON DELETE NO ACTION
198
) ENGINE = InnoDB;
199
200


201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
-- Define the package relation types
--
CREATE TABLE RelationTypes (
	ID TINYINT UNSIGNED NOT NULL AUTO_INCREMENT,
	Name VARCHAR(32) NOT NULL DEFAULT '',
	PRIMARY KEY (ID)
) ENGINE = InnoDB;
INSERT INTO RelationTypes VALUES (1, 'conflicts');
INSERT INTO RelationTypes VALUES (2, 'provides');
INSERT INTO RelationTypes VALUES (3, 'replaces');


-- Track which conflicts, provides and replaces a package has
--
CREATE TABLE PackageRelations (
	PackageID INTEGER UNSIGNED NOT NULL,
	RelTypeID TINYINT UNSIGNED NOT NULL,
	RelName VARCHAR(255) NOT NULL,
219
	RelCondition VARCHAR(255),
220
	RelArch VARCHAR(255) NULL DEFAULT NULL,
221
222
223
224
225
226
227
	INDEX (PackageID),
	INDEX (RelName),
	FOREIGN KEY (PackageID) REFERENCES Packages(ID) ON DELETE CASCADE,
	FOREIGN KEY (RelTypeID) REFERENCES RelationTypes(ID) ON DELETE NO ACTION
) ENGINE = InnoDB;


228
229
230
231
-- Track which sources a package has
--
CREATE TABLE PackageSources (
	PackageID INTEGER UNSIGNED NOT NULL,
232
	Source VARCHAR(255) NOT NULL DEFAULT "/dev/null",
233
	SourceArch VARCHAR(255) NULL DEFAULT NULL,
234
235
	INDEX (PackageID),
	FOREIGN KEY (PackageID) REFERENCES Packages(ID) ON DELETE CASCADE
236
) ENGINE = InnoDB;
237
238


eric's avatar
eric committed
239
240
241
-- Track votes for packages
--
CREATE TABLE PackageVotes (
242
	UsersID INTEGER UNSIGNED NOT NULL,
243
	PackageBaseID INTEGER UNSIGNED NOT NULL,
244
	VoteTS BIGINT UNSIGNED NULL DEFAULT NULL,
245
	INDEX (UsersID),
246
	INDEX (PackageBaseID),
247
	FOREIGN KEY (UsersID) REFERENCES Users(ID) ON DELETE CASCADE,
248
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE
249
) ENGINE = InnoDB;
250
CREATE UNIQUE INDEX VoteUsersIDPackageID ON PackageVotes (UsersID, PackageBaseID);
eric's avatar
eric committed
251

eric's avatar
eric committed
252
-- Record comments for packages
253
--
eric's avatar
eric committed
254
CREATE TABLE PackageComments (
255
	ID BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
256
	PackageBaseID INTEGER UNSIGNED NOT NULL,
257
	UsersID INTEGER UNSIGNED NULL DEFAULT NULL,
Loui Chang's avatar
Loui Chang committed
258
	Comments TEXT NOT NULL DEFAULT '',
eric's avatar
eric committed
259
	CommentTS BIGINT UNSIGNED NOT NULL DEFAULT 0,
260
261
	EditedTS BIGINT UNSIGNED NULL DEFAULT NULL,
	EditedUsersID INTEGER UNSIGNED NULL DEFAULT NULL,
262
	DelUsersID INTEGER UNSIGNED NULL DEFAULT NULL,
263
	PRIMARY KEY (ID),
264
	INDEX (UsersID),
265
	INDEX (PackageBaseID),
Lukas Fleischer's avatar
Lukas Fleischer committed
266
	FOREIGN KEY (UsersID) REFERENCES Users(ID) ON DELETE SET NULL,
267
	FOREIGN KEY (EditedUsersID) REFERENCES Users(ID) ON DELETE SET NULL,
eric's avatar
eric committed
268
	FOREIGN KEY (DelUsersID) REFERENCES Users(ID) ON DELETE CASCADE,
269
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE
270
) ENGINE = InnoDB;
271

272
273
274
275
276
-- Package base co-maintainers
--
CREATE TABLE PackageComaintainers (
	UsersID INTEGER UNSIGNED NOT NULL,
	PackageBaseID INTEGER UNSIGNED NOT NULL,
277
	Priority INTEGER UNSIGNED NOT NULL,
278
279
280
281
282
283
	INDEX (UsersID),
	INDEX (PackageBaseID),
	FOREIGN KEY (UsersID) REFERENCES Users(ID) ON DELETE CASCADE,
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE
) ENGINE = InnoDB;

284
285
286
-- Comment addition notifications
--
CREATE TABLE CommentNotify (
287
	PackageBaseID INTEGER UNSIGNED NOT NULL,
288
	UserID INTEGER UNSIGNED NOT NULL,
289
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE,
290
	FOREIGN KEY (UserID) REFERENCES Users(ID) ON DELETE CASCADE
291
) ENGINE = InnoDB;
292
CREATE UNIQUE INDEX NotifyUserIDPkgID ON CommentNotify (UserID, PackageBaseID);
293

294
295
296
297
-- Package name blacklist
--
CREATE TABLE PackageBlacklist (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
298
	Name VARCHAR(64) NOT NULL,
299
300
	PRIMARY KEY (ID),
	UNIQUE (Name)
301
) ENGINE = InnoDB;
302

303
304
305
306
307
308
309
310
311
-- Define package request types
--
CREATE TABLE RequestTypes (
	ID TINYINT UNSIGNED NOT NULL AUTO_INCREMENT,
	Name VARCHAR(32) NOT NULL DEFAULT '',
	PRIMARY KEY (ID)
) ENGINE = InnoDB;
INSERT INTO RequestTypes VALUES (1, 'deletion');
INSERT INTO RequestTypes VALUES (2, 'orphan');
312
INSERT INTO RequestTypes VALUES (3, 'merge');
313
314
315
316
317
318
319
320

-- Package requests
--
CREATE TABLE PackageRequests (
	ID BIGINT UNSIGNED NOT NULL AUTO_INCREMENT,
	ReqTypeID TINYINT UNSIGNED NOT NULL,
	PackageBaseID INTEGER UNSIGNED NULL,
	PackageBaseName VARCHAR(255) NOT NULL,
321
	MergeBaseName VARCHAR(255) NULL,
322
323
324
	UsersID INTEGER UNSIGNED NULL DEFAULT NULL,
	Comments TEXT NOT NULL DEFAULT '',
	RequestTS BIGINT UNSIGNED NOT NULL DEFAULT 0,
325
	Status TINYINT UNSIGNED NOT NULL DEFAULT 0,
326
327
328
329
330
331
332
333
	PRIMARY KEY (ID),
	INDEX (UsersID),
	INDEX (PackageBaseID),
	FOREIGN KEY (ReqTypeID) REFERENCES RequestTypes(ID) ON DELETE NO ACTION,
	FOREIGN KEY (UsersID) REFERENCES Users(ID) ON DELETE SET NULL,
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE SET NULL
) ENGINE = InnoDB;

Callan Barrett's avatar
Callan Barrett committed
334
335
336
-- Vote information
--
CREATE TABLE IF NOT EXISTS TU_VoteInfo (
337
338
339
340
341
342
343
344
345
346
347
348
349
	ID int(10) unsigned NOT NULL auto_increment,
	Agenda text NOT NULL,
	User VARCHAR(32) NOT NULL,
	Submitted bigint(20) unsigned NOT NULL,
	End bigint(20) unsigned NOT NULL,
	Quorum decimal(2, 2) unsigned NOT NULL,
	SubmitterID int(10) unsigned NOT NULL,
	Yes tinyint(3) unsigned NOT NULL default '0',
	No tinyint(3) unsigned NOT NULL default '0',
	Abstain tinyint(3) unsigned NOT NULL default '0',
	ActiveTUs tinyint(3) unsigned NOT NULL default '0',
	PRIMARY KEY  (ID),
	FOREIGN KEY (SubmitterID) REFERENCES Users(ID) ON DELETE CASCADE
350
) ENGINE = InnoDB;
Callan Barrett's avatar
Callan Barrett committed
351
352
353
354

-- Individual vote records
--
CREATE TABLE IF NOT EXISTS TU_Votes (
355
356
357
358
	VoteID int(10) unsigned NOT NULL,
	UserID int(10) unsigned NOT NULL,
	FOREIGN KEY (VoteID) REFERENCES TU_VoteInfo(ID) ON DELETE CASCADE,
	FOREIGN KEY (UserID) REFERENCES Users(ID) ON DELETE CASCADE
359
) ENGINE = InnoDB;
360
361
362
363
364
365
366
367

-- Malicious user banning
--
CREATE TABLE Bans (
	IPAddress INTEGER UNSIGNED NOT NULL DEFAULT 0,
	BanTS TIMESTAMP NOT NULL,
	PRIMARY KEY (IPAddress)
) ENGINE = InnoDB;