aur-schema.sql 12.3 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
	Username VARCHAR(32) NOT NULL,
28
	Email VARCHAR(254) NOT NULL,
29
	HideEmail TINYINT UNSIGNED NOT NULL DEFAULT 0,
eric's avatar
eric committed
30
	Passwd CHAR(32) NOT NULL,
Denis's avatar
Denis committed
31
	Salt CHAR(32) NOT NULL DEFAULT '',
32
	ResetKey CHAR(32) NOT NULL DEFAULT '',
33
	RealName VARCHAR(64) NOT NULL DEFAULT '',
34
	LangPreference VARCHAR(6) NOT NULL DEFAULT 'en',
35
	Homepage TEXT NULL DEFAULT NULL,
36
	IRCNick VARCHAR(32) NOT NULL DEFAULT '',
37
	PGPKey VARCHAR(40) NULL DEFAULT NULL,
38
	LastLogin BIGINT UNSIGNED NOT NULL DEFAULT 0,
39
	LastLoginIPAddress VARCHAR(45) NULL DEFAULT NULL,
40
	InactivityTS BIGINT UNSIGNED NOT NULL DEFAULT 0,
41
	RegistrationTS TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP,
42
	CommentNotify TINYINT(1) NOT NULL DEFAULT 1,
43
	UpdateNotify TINYINT(1) NOT NULL DEFAULT 0,
44
	OwnershipNotify TINYINT(1) NOT NULL DEFAULT 1,
eric's avatar
eric committed
45
	PRIMARY KEY (ID),
eric's avatar
eric committed
46
	UNIQUE (Username),
47
48
49
	UNIQUE (Email),
	INDEX (AccountTypeID),
	FOREIGN KEY (AccountTypeID) REFERENCES AccountTypes(ID) ON DELETE NO ACTION
50
) ENGINE = InnoDB;
eric's avatar
eric committed
51
-- A default developer account for testing purposes
52
INSERT INTO Users (ID, AccountTypeID, Username, Email, Passwd) VALUES (
53
	1, 3, 'dev', 'dev@localhost', MD5('dev'));
eric's avatar
eric committed
54
INSERT INTO Users (ID, AccountTypeID, Username, Email, Passwd) VALUES (
55
	2, 2, 'tu', 'tu@localhost', MD5('tu'));
eric's avatar
eric committed
56
INSERT INTO Users (ID, AccountTypeID, Username, Email, Passwd) VALUES (
57
	3, 1, 'user', 'user@localhost', MD5('user'));
eric's avatar
eric committed
58
59


60
61
62
63
64
65
66
67
68
69
70
-- 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
71
72
73
-- Track Users logging in/out of AUR web site.
--
CREATE TABLE Sessions (
74
	UsersID INTEGER UNSIGNED NOT NULL,
eric's avatar
eric committed
75
	SessionID CHAR(32) NOT NULL,
76
	LastUpdateTS BIGINT UNSIGNED NOT NULL,
77
	FOREIGN KEY (UsersID) REFERENCES Users(ID) ON DELETE CASCADE,
eric's avatar
eric committed
78
	UNIQUE (SessionID)
79
) ENGINE = InnoDB;
eric's avatar
eric committed
80
81


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


111
112
113
114
115
116
117
118
119
120
-- 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;


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


-- Information about licenses
--
CREATE TABLE Licenses (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
140
	Name VARCHAR(255) NOT NULL,
141
142
143
144
145
146
147
148
149
150
151
152
153
	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
154
155
156
) ENGINE = InnoDB;


157
158
159
160
-- Information about groups
--
CREATE TABLE Groups (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
161
	Name VARCHAR(255) NOT NULL,
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
	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;


178
179
180
181
182
183
184
185
186
187
188
189
190
-- 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');


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


206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
-- 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,
224
	RelCondition VARCHAR(255),
225
	RelArch VARCHAR(255) NULL DEFAULT NULL,
226
227
228
229
230
231
232
	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;


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


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

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

279
280
281
282
283
-- Package base co-maintainers
--
CREATE TABLE PackageComaintainers (
	UsersID INTEGER UNSIGNED NOT NULL,
	PackageBaseID INTEGER UNSIGNED NOT NULL,
284
	Priority INTEGER UNSIGNED NOT NULL,
285
286
287
288
289
290
	INDEX (UsersID),
	INDEX (PackageBaseID),
	FOREIGN KEY (UsersID) REFERENCES Users(ID) ON DELETE CASCADE,
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE
) ENGINE = InnoDB;

291
-- Package base notifications
292
--
293
CREATE TABLE PackageNotifications (
294
	PackageBaseID INTEGER UNSIGNED NOT NULL,
295
	UserID INTEGER UNSIGNED NOT NULL,
296
	FOREIGN KEY (PackageBaseID) REFERENCES PackageBases(ID) ON DELETE CASCADE,
297
	FOREIGN KEY (UserID) REFERENCES Users(ID) ON DELETE CASCADE
298
) ENGINE = InnoDB;
299
CREATE UNIQUE INDEX NotifyUserIDPkgID ON PackageNotifications (UserID, PackageBaseID);
300

301
302
303
304
-- Package name blacklist
--
CREATE TABLE PackageBlacklist (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
305
	Name VARCHAR(64) NOT NULL,
306
307
	PRIMARY KEY (ID),
	UNIQUE (Name)
308
) ENGINE = InnoDB;
309

310
311
312
313
314
-- Providers in the official repositories
--
CREATE TABLE OfficialProviders (
	ID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT,
	Name VARCHAR(64) NOT NULL,
315
	Repo VARCHAR(64) NOT NULL,
316
317
318
319
320
	Provides VARCHAR(64) NOT NULL,
	PRIMARY KEY (ID)
) ENGINE = InnoDB;
CREATE UNIQUE INDEX ProviderNameProvides ON OfficialProviders (Name, Provides);

321
322
323
324
325
326
327
328
329
-- 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');
330
INSERT INTO RequestTypes VALUES (3, 'merge');
331
332
333
334
335
336
337
338

-- 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,
339
	MergeBaseName VARCHAR(255) NULL,
340
341
	UsersID INTEGER UNSIGNED NULL DEFAULT NULL,
	Comments TEXT NOT NULL DEFAULT '',
342
	ClosureComment TEXT NOT NULL DEFAULT '',
343
	RequestTS BIGINT UNSIGNED NOT NULL DEFAULT 0,
344
	Status TINYINT UNSIGNED NOT NULL DEFAULT 0,
345
346
347
348
349
350
351
352
	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
353
354
355
-- Vote information
--
CREATE TABLE IF NOT EXISTS TU_VoteInfo (
356
357
358
359
360
361
362
363
364
365
366
367
368
	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
369
) ENGINE = InnoDB;
Callan Barrett's avatar
Callan Barrett committed
370
371
372
373

-- Individual vote records
--
CREATE TABLE IF NOT EXISTS TU_Votes (
374
375
376
377
	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
378
) ENGINE = InnoDB;
379
380
381
382
383
384
385
386

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