Add editorial and description columns
[gruntmaster-data.git] / db.sql
1 CREATE TABLE users (
2 id TEXT PRIMARY KEY,
3 passphrase TEXT, -- NOT NULL,
4 admin BOOLEAN NOT NULL DEFAULT FALSE,
5 name TEXT, -- NOT NULL,
6 email TEXT, -- NOT NULL,
7 phone TEXT, -- NOT NULL,
8 town TEXT, -- NOT NULL,
9 university TEXT, -- NOT NULL,
10 level TEXT, -- NOT NULL,
11 country TEXT,
12 lastjob BIGINT,
13 since BIGINT DEFAULT CAST(EXTRACT(epoch from now()) AS bigint)
14 );
15
16 CREATE TABLE contests (
17 id TEXT PRIMARY KEY,
18 name TEXT NOT NULL,
19 editorial TEXT,
20 description TEXT,
21 start INT NOT NULL,
22 stop INT NOT NULL,
23 owner TEXT NOT NULL REFERENCES users ON DELETE CASCADE,
24 CONSTRAINT positive_duration CHECK (stop > start)
25 );
26
27 CREATE TABLE contest_status (
28 contest TEXT NOT NULL REFERENCES contests ON DELETE CASCADE,
29 owner TEXT NOT NULL REFERENCES users ON DELETE CASCADE,
30 score INT NOT NULL,
31 rank INT NOT NULL,
32
33 PRIMARY KEY (owner, contest)
34 );
35
36 CREATE TABLE problems (
37 id TEXT PRIMARY KEY,
38 author TEXT,
39 writer TEXT,
40 generator TEXT NOT NULL,
41 judge TEXT NOT NULL,
42 level TEXT NOT NULL,
43 name TEXT NOT NULL,
44 olimit INT,
45 owner TEXT NOT NULL REFERENCES users ON DELETE CASCADE,
46 private BOOLEAN NOT NULL DEFAULT FALSE,
47 runner TEXT NOT NULL,
48 solution TEXT ,
49 statement TEXT NOT NULL,
50 testcnt INT NOT NULL,
51 precnt INT,
52 tests TEXT,
53 timeout REAL NOT NULL,
54 value INT NOT NULL,
55 genformat TEXT,
56 gensource TEXT,
57 verformat TEXT,
58 versource TEXT
59 );
60
61 CREATE TABLE contest_problems (
62 contest TEXT REFERENCES contests ON DELETE CASCADE,
63 problem TEXT NOT NULL REFERENCES problems ON DELETE CASCADE,
64 PRIMARY KEY (contest, problem)
65 );
66
67 CREATE TABLE jobs (
68 id SERIAL PRIMARY KEY,
69 contest TEXT REFERENCES contests ON DELETE CASCADE,
70 daemon TEXT,
71 date BIGINT NOT NULL,
72 errors TEXT,
73 extension TEXT NOT NULL,
74 format TEXT NOT NULL,
75 private BOOLEAN NOT NULL DEFAULT FALSE,
76 problem TEXT NOT NULL REFERENCES problems ON DELETE CASCADE,
77 result INT,
78 result_text TEXT,
79 results TEXT,
80 source TEXT NOT NULL,
81 owner TEXT NOT NULL REFERENCES users ON DELETE CASCADE
82 );
83
84 CREATE TABLE problem_status (
85 problem TEXT NOT NULL REFERENCES problems ON DELETE CASCADE,
86 owner TEXT NOT NULL REFERENCES users ON DELETE CASCADE,
87 job SERIAL NOT NULL REFERENCES jobs ON DELETE CASCADE,
88 solved BOOLEAN NOT NULL DEFAULT FALSE,
89
90 PRIMARY KEY (owner, problem)
91 );
92
93 CREATE TABLE opens (
94 contest TEXT NOT NULL REFERENCES contests ON DELETE CASCADE,
95 problem TEXT NOT NULL REFERENCES problems ON DELETE CASCADE,
96 owner TEXT NOT NULL REFERENCES users ON DELETE CASCADE,
97 time BIGINT NOT NULL,
98 PRIMARY KEY (contest, problem, owner)
99 );
100
101 CREATE TABLE table_comments (
102 table_name TEXT NOT NULL PRIMARY KEY,
103 comment_text TEXT NOT NULL
104 );
105
106 CREATE TABLE column_comments (
107 table_name TEXT NOT NULL,
108 column_name TEXT NOT NULL,
109 comment_text TEXT NOT NULL,
110 PRIMARY KEY (table_name, column_name)
111 );
112
113 INSERT INTO table_comments VALUES ('users', 'List of users');
114 INSERT INTO table_comments VALUES ('contests', 'List of contests');
115 INSERT INTO table_comments VALUES ('contest_status', 'List of (contest, user, result)');
116 INSERT INTO table_comments VALUES ('problems', 'List of problems');
117 INSERT INTO table_comments VALUES ('contest_problems', 'Many-to-many bridge between contests and problems');
118 INSERT INTO table_comments VALUES ('jobs', 'List of jobs');
119 INSERT INTO table_comments VALUES ('problem_status', 'List of (problem, user, result)');
120 INSERT INTO table_comments VALUES ('opens', 'List of (contest, problem, user, time when user opened problem)');
121
122 INSERT INTO column_comments VALUES ('users', 'passphrase', 'RFC2307-encoded passphrase');
123 INSERT INTO column_comments VALUES ('users', 'name', 'Full name of user');
124 INSERT INTO column_comments VALUES ('users', 'level', 'Highschool, Undergraduate, Master, Doctorate or Other');
125 INSERT INTO column_comments VALUES ('users', 'lastjob', 'Unix time when this user last submitted a job');
126 INSERT INTO column_comments VALUES ('users', 'since', 'Unix time when this user was created');
127
128 INSERT INTO column_comments VALUES ('contests', 'start', 'Unix time when contest starts');
129 INSERT INTO column_comments VALUES ('contests', 'stop', 'Unix time when contest ends');
130 INSERT INTO column_comments VALUES ('contests', 'editorial', 'HTML fragment placed before the editorial');
131 INSERT INTO column_comments VALUES ('contests', 'description', 'HTML fragment placed on contest page');
132
133 INSERT INTO column_comments VALUES ('problems', 'author', 'Full name(s) of problem author(s)/problemsetter(s)/tester(s)/etc');
134 INSERT INTO column_comments VALUES ('problems', 'writer', 'Full name(s) of statement writer(s) (DEPRECATED)');
135 INSERT INTO column_comments VALUES ('problems', 'generator', 'Generator class, without the leading Gruntmaster::Daemon::Generator::');
136 INSERT INTO column_comments VALUES ('problems', 'runner', 'Runner class, without the leading Gruntmaster::Daemon::Runner::');
137 INSERT INTO column_comments VALUES ('problems', 'judge', 'Judge class, without the leading Gruntmaster::Daemon::Judge::');
138 INSERT INTO column_comments VALUES ('problems', 'level', 'Problem level, one of beginner, easy, medium, hard');
139 INSERT INTO column_comments VALUES ('problems', 'olimit', 'Output limit (in bytes)');
140 INSERT INTO column_comments VALUES ('problems', 'timeout', 'Time limit (in seconds)');
141 INSERT INTO column_comments VALUES ('problems', 'solution', 'Solution (HTML)');
142 INSERT INTO column_comments VALUES ('problems', 'statement', 'Statement (HTML)');
143 INSERT INTO column_comments VALUES ('problems', 'testcnt', 'Number of tests');
144 INSERT INTO column_comments VALUES ('problems', 'precnt', 'Number of pretests. NULL indicates full feedback.');
145 INSERT INTO column_comments VALUES ('problems', 'tests', 'JSON array of test values for ::Runner::File');
146 INSERT INTO column_comments VALUES ('problems', 'value', 'Problem value when used in a contest.');
147 INSERT INTO column_comments VALUES ('problems', 'genformat', 'Format (programming language) of the generator if using the Run generator');
148 INSERT INTO column_comments VALUES ('problems', 'gensource', 'Source code of generator if using the Run generator');
149 INSERT INTO column_comments VALUES ('problems', 'verformat', 'Format (programming language) of the verifier if using the Verifier runner');
150 INSERT INTO column_comments VALUES ('problems', 'versource', 'Source code of verifier if using the Verifier runner');
151
152 INSERT INTO column_comments VALUES ('jobs', 'daemon', 'hostname:PID of daemon that last executed this job. NULL if never executed');
153 INSERT INTO column_comments VALUES ('jobs', 'date', 'Unix time when job was submitted');
154 INSERT INTO column_comments VALUES ('jobs', 'errors', 'Compiler errors');
155 INSERT INTO column_comments VALUES ('jobs', 'extension', 'File extension of submitted program, without a leading dot');
156 INSERT INTO column_comments VALUES ('jobs', 'format', 'Format (programming language) of submitted program');
157 INSERT INTO column_comments VALUES ('jobs', 'result', 'Job result (integer constant from Gruntmaster::Daemon::Constants)');
158 INSERT INTO column_comments VALUES ('jobs', 'result_text', 'Job result (human-readable text)');
159 INSERT INTO column_comments VALUES ('jobs', 'results', 'Per-test results (JSON array of hashes with keys id (test number, counting from 1), result (integer constant from Gruntmaster::Daemon::Constants), result_text (human-readable text), time (execution time in decimal seconds))');
160
161 INSERT INTO column_comments VALUES ('problem_status', 'solved', 'True if the result is Accepted, False otherwise');
This page took 0.025699 seconds and 5 git commands to generate.