summaryrefslogtreecommitdiff
path: root/sourcemod/scripting/gokz-localdb/db/sql.sp
blob: 46ea5e3b5a42e6768fcb278c3f7e1cb3b3807719 (plain)
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
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
/*
	SQL query templates.
*/



// =====[ PLAYERS ]=====

char sqlite_players_create[] = "\
CREATE TABLE IF NOT EXISTS Players ( \
    SteamID32 INTEGER NOT NULL, \
    Alias TEXT, \
    Country TEXT, \
    IP TEXT, \
    Cheater INTEGER NOT NULL DEFAULT '0', \
    LastPlayed TIMESTAMP NULL DEFAULT NULL, \
    Created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Player PRIMARY KEY (SteamID32))";

char mysql_players_create[] = "\
CREATE TABLE IF NOT EXISTS Players ( \
    SteamID32 INTEGER UNSIGNED NOT NULL, \
    Alias VARCHAR(32), \
    Country VARCHAR(45), \
    IP VARCHAR(15), \
    Cheater TINYINT UNSIGNED NOT NULL DEFAULT '0', \
    LastPlayed TIMESTAMP NULL DEFAULT NULL, \
    Created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Player PRIMARY KEY (SteamID32))";

char sqlite_players_insert[] = "\
INSERT OR IGNORE INTO Players (Alias, Country, IP, SteamID32, LastPlayed) \
    VALUES ('%s', '%s', '%s', %d, CURRENT_TIMESTAMP)";

char sqlite_players_update[] = "\
UPDATE OR IGNORE Players \
    SET Alias='%s', Country='%s', IP='%s', LastPlayed=CURRENT_TIMESTAMP \
    WHERE SteamID32=%d";

char mysql_players_upsert[] = "\
INSERT INTO Players (Alias, Country, IP, SteamID32, LastPlayed) \
    VALUES ('%s', '%s', '%s', %d, CURRENT_TIMESTAMP) \
    ON DUPLICATE KEY UPDATE \
    SteamID32=VALUES(SteamID32), Alias=VALUES(Alias), Country=VALUES(Country), \
    IP=VALUES(IP), LastPlayed=VALUES(LastPlayed)";

char sql_players_get_cheater[] = "\
SELECT Cheater \
    FROM Players \
    WHERE SteamID32=%d";

char sql_players_set_cheater[] = "\
UPDATE Players \
    SET Cheater=%d \
    WHERE SteamID32=%d";



// =====[ MAPS ]=====

char sqlite_maps_create[] = "\
CREATE TABLE IF NOT EXISTS Maps ( \
    MapID INTEGER NOT NULL, \
    Name VARCHAR(32) NOT NULL UNIQUE, \
    LastPlayed TIMESTAMP NULL DEFAULT NULL, \
    Created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Maps PRIMARY KEY (MapID))";

char mysql_maps_create[] = "\
CREATE TABLE IF NOT EXISTS Maps ( \
    MapID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, \
    Name VARCHAR(32) NOT NULL UNIQUE, \
    LastPlayed TIMESTAMP NULL DEFAULT NULL, \
    Created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Maps PRIMARY KEY (MapID))";

char sqlite_maps_insert[] = "\
INSERT OR IGNORE INTO Maps (Name, LastPlayed) \
    VALUES ('%s', CURRENT_TIMESTAMP)";

char sqlite_maps_update[] = "\
UPDATE OR IGNORE Maps \
    SET LastPlayed=CURRENT_TIMESTAMP \
    WHERE Name='%s'";

char mysql_maps_upsert[] = "\
INSERT INTO Maps (Name, LastPlayed) \
    VALUES ('%s', CURRENT_TIMESTAMP) \
    ON DUPLICATE KEY UPDATE \
    LastPlayed=CURRENT_TIMESTAMP";

char sql_maps_findid[] = "\
SELECT MapID, Name \
    FROM Maps \
    WHERE Name LIKE '%%%s%%' \
    ORDER BY (Name='%s') DESC, LENGTH(Name) \
    LIMIT 1";



// =====[ MAPCOURSES ]=====

char sqlite_mapcourses_create[] = "\
CREATE TABLE IF NOT EXISTS MapCourses ( \
    MapCourseID INTEGER NOT NULL, \
    MapID INTEGER NOT NULL, \
    Course INTEGER NOT NULL, \
    Created INTEGER NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_MapCourses PRIMARY KEY (MapCourseID), \
    CONSTRAINT UQ_MapCourses_MapIDCourse UNIQUE (MapID, Course), \
    CONSTRAINT FK_MapCourses_MapID FOREIGN KEY (MapID) REFERENCES Maps(MapID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char mysql_mapcourses_create[] = "\
CREATE TABLE IF NOT EXISTS MapCourses ( \
    MapCourseID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, \
    MapID INTEGER UNSIGNED NOT NULL, \
    Course INTEGER UNSIGNED NOT NULL, \
    Created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_MapCourses PRIMARY KEY (MapCourseID), \
    CONSTRAINT UQ_MapCourses_MapIDCourse UNIQUE (MapID, Course), \
    CONSTRAINT FK_MapCourses_MapID FOREIGN KEY (MapID) REFERENCES Maps(MapID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char sqlite_mapcourses_insert[] = "\
INSERT OR IGNORE INTO MapCourses (MapID, Course) \
    VALUES (%d, %d)";

char mysql_mapcourses_insert[] = "\
INSERT IGNORE INTO MapCourses (MapID, Course) \
    VALUES (%d, %d)";



// =====[ TIMES ]=====

char sqlite_times_create[] = "\
CREATE TABLE IF NOT EXISTS Times ( \
    TimeID INTEGER NOT NULL, \
    SteamID32 INTEGER NOT NULL, \
    MapCourseID INTEGER NOT NULL, \
    Mode INTEGER NOT NULL, \
    Style INTEGER NOT NULL, \
    RunTime INTEGER NOT NULL, \
    Teleports INTEGER NOT NULL, \
    Created INTEGER NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Times PRIMARY KEY (TimeID), \
    CONSTRAINT FK_Times_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32) \
    ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT FK_Times_MapCourseID \
    FOREIGN KEY (MapCourseID) REFERENCES MapCourses(MapCourseID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char mysql_times_create[] = "\
CREATE TABLE IF NOT EXISTS Times ( \
    TimeID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, \
    SteamID32 INTEGER UNSIGNED NOT NULL, \
    MapCourseID INTEGER UNSIGNED NOT NULL, \
    Mode TINYINT UNSIGNED NOT NULL, \
    Style TINYINT UNSIGNED NOT NULL, \
    RunTime INTEGER UNSIGNED NOT NULL, \
    Teleports SMALLINT UNSIGNED NOT NULL, \
    Created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Times PRIMARY KEY (TimeID), \
    CONSTRAINT FK_Times_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32) \
    ON UPDATE CASCADE ON DELETE CASCADE, \
    CONSTRAINT FK_Times_MapCourseID FOREIGN KEY (MapCourseID) REFERENCES MapCourses(MapCourseID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char sql_times_insert[] = "\
INSERT INTO Times (SteamID32, MapCourseID, Mode, Style, RunTime, Teleports) \
    SELECT %d, MapCourseID, %d, %d, %d, %d \
    FROM MapCourses \
    WHERE MapID=%d AND Course=%d";

char sql_times_delete[] = "\
DELETE FROM Times \
    WHERE TimeID=%d";



// =====[ JUMPSTATS ]=====

char sqlite_jumpstats_create[] = "\
CREATE TABLE IF NOT EXISTS Jumpstats ( \
    JumpID INTEGER NOT NULL, \
    SteamID32 INTEGER NOT NULL, \
    JumpType INTEGER NOT NULL, \
    Mode INTEGER NOT NULL, \
    Distance INTEGER NOT NULL, \
    IsBlockJump INTEGER NOT NULL, \
    Block INTEGER NOT NULL, \
    Strafes INTEGER NOT NULL, \
    Sync INTEGER NOT NULL, \
    Pre INTEGER NOT NULL, \
    Max INTEGER NOT NULL, \
    Airtime INTEGER NOT NULL, \
    Created INTEGER NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Jumpstats PRIMARY KEY (JumpID), \
    CONSTRAINT FK_Jumpstats_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char mysql_jumpstats_create[] = "\
CREATE TABLE IF NOT EXISTS Jumpstats ( \
    JumpID INTEGER UNSIGNED NOT NULL AUTO_INCREMENT, \
    SteamID32 INTEGER UNSIGNED NOT NULL, \
    JumpType TINYINT UNSIGNED NOT NULL, \
    Mode TINYINT UNSIGNED NOT NULL, \
    Distance INTEGER UNSIGNED NOT NULL, \
    IsBlockJump TINYINT UNSIGNED NOT NULL, \
    Block SMALLINT UNSIGNED NOT NULL, \
    Strafes INTEGER UNSIGNED NOT NULL, \
    Sync INTEGER UNSIGNED NOT NULL, \
    Pre INTEGER UNSIGNED NOT NULL, \
    Max INTEGER UNSIGNED NOT NULL, \
    Airtime INTEGER UNSIGNED NOT NULL, \
    Created TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP, \
    CONSTRAINT PK_Jumpstats PRIMARY KEY (JumpID), \
    CONSTRAINT FK_Jumpstats_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char sql_jumpstats_insert[] = "\
INSERT INTO Jumpstats (SteamID32, JumpType, Mode, Distance, IsBlockJump, Block, Strafes, Sync, Pre, Max, Airtime) \
    VALUES (%d, %d, %d, %d, %d, %d, %d, %d, %d, %d, %d)";

char sql_jumpstats_update[] = "\
UPDATE Jumpstats \
    SET \
        SteamID32=%d, \
        JumpType=%d, \
        Mode=%d, \
        Distance=%d, \
        IsBlockJump=%d, \
        Block=%d, \
        Strafes=%d, \
        Sync=%d, \
        Pre=%d, \
        Max=%d, \
        Airtime=%d \
    WHERE \
        JumpID=%d";

char sql_jumpstats_getrecord[] = "\
SELECT JumpID, Distance, Block \
    FROM \
        Jumpstats \
    WHERE \
        SteamID32=%d AND \
        JumpType=%d AND \
        Mode=%d AND \
        IsBlockJump=%d \
    ORDER BY Block DESC, Distance DESC";

char sql_jumpstats_deleterecord[] = "\
DELETE \
    FROM \
        Jumpstats \
    WHERE \
        JumpID = \
        ( SELECT * FROM ( \
            SELECT JumpID \
                FROM \
                    Jumpstats \
                WHERE \
                    SteamID32=%d AND \
                    JumpType=%d AND \
                    Mode=%d AND \
                    IsBlockJump=%d \
                ORDER BY Block DESC, Distance DESC \
                LIMIT 1 \
			) AS tmp \
        )";

char sql_jumpstats_deleteallrecords[] = "\
DELETE \
	FROM \
		Jumpstats \
	WHERE \
		SteamID32 = %d;";

char sql_jumpstats_deletejump[] = "\
DELETE \
	FROM \
		Jumpstats \
	WHERE \
		JumpID = %d;";

char sql_jumpstats_getpbs[] = "\
SELECT MAX(Distance), Mode, JumpType \
    FROM \
        Jumpstats \
    WHERE \
        SteamID32=%d \
    GROUP BY \
    	Mode, JumpType";

char sql_jumpstats_getblockpbs[] = "\
SELECT MAX(js.Distance), js.Mode, js.JumpType, js.Block \
	FROM \
		Jumpstats js \
	INNER JOIN \
	( \
		SELECT Mode, JumpType, MAX(BLOCK) Block \
			FROM \
				Jumpstats \
			WHERE \
				IsBlockJump=1 AND \
				SteamID32=%d \
			GROUP BY \ 
				Mode, JumpType \
	) pb \
	ON \
		js.Mode=pb.Mode AND \
		js.JumpType=pb.JumpType AND \
		js.Block=pb.Block \
	WHERE \
		js.SteamID32=%d \
	GROUP BY \
		js.Mode, js.JumpType, js.Block";



// =====[ VB POSITIONS ]=====

char sqlite_vbpos_create[] = "\
CREATE TABLE IF NOT EXISTS VBPosition ( \
	SteamID32 INTEGER NOT NULL, \
	MapID INTEGER NOT NULL, \
	X REAL NOT NULL, \
	Y REAL NOT NULL, \
	Z REAL NOT NULL, \
	Course INTEGER NOT NULL, \
	IsStart INTEGER NOT NULL, \
	CONSTRAINT PK_VBPosition PRIMARY KEY (SteamID32, MapID, IsStart), \
    CONSTRAINT FK_VBPosition_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32), \
    CONSTRAINT FK_VBPosition_MapID FOREIGN KEY (MapID) REFERENCES Maps(MapID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char mysql_vbpos_create[] = "\
CREATE TABLE IF NOT EXISTS VBPosition ( \
	SteamID32 INTEGER UNSIGNED NOT NULL, \
	MapID INTEGER UNSIGNED NOT NULL, \
	X REAL NOT NULL, \
	Y REAL NOT NULL, \
	Z REAL NOT NULL, \
	Course INTEGER NOT NULL, \
	IsStart INTEGER NOT NULL, \
	CONSTRAINT PK_VBPosition PRIMARY KEY (SteamID32, MapID, IsStart), \
    CONSTRAINT FK_VBPosition_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32), \
    CONSTRAINT FK_VBPosition_MapID FOREIGN KEY (MapID) REFERENCES Maps(MapID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char sql_vbpos_upsert[] = "\
REPLACE INTO VBPosition (SteamID32, MapID, X, Y, Z, Course, IsStart) \
	VALUES (%d, %d, %f, %f, %f, %d, %d)";

char sql_vbpos_get[] = "\
SELECT SteamID32, MapID, Course, IsStart, X, Y, Z \
	FROM \
		VBPosition \
	WHERE \
		SteamID32 = %d AND \
		MapID = %d";



// =====[ START POSITIONS ]=====

char sqlite_startpos_create[] = "\
CREATE TABLE IF NOT EXISTS StartPosition ( \
	SteamID32 INTEGER NOT NULL, \
	MapID INTEGER NOT NULL, \
	X REAL NOT NULL, \
	Y REAL NOT NULL, \
	Z REAL NOT NULL, \
	Angle0 REAL NOT NULL, \
	Angle1 REAL NOT NULL, \
	CONSTRAINT PK_StartPosition PRIMARY KEY (SteamID32, MapID), \
    CONSTRAINT FK_StartPosition_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32) \
    CONSTRAINT FK_StartPosition_MapID FOREIGN KEY (MapID) REFERENCES Maps(MapID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char mysql_startpos_create[] = "\
CREATE TABLE IF NOT EXISTS StartPosition ( \
	SteamID32 INTEGER UNSIGNED NOT NULL, \
	MapID INTEGER UNSIGNED NOT NULL, \
	X REAL NOT NULL, \
	Y REAL NOT NULL, \
	Z REAL NOT NULL, \
	Angle0 REAL NOT NULL, \
	Angle1 REAL NOT NULL, \
	CONSTRAINT PK_StartPosition PRIMARY KEY (SteamID32, MapID), \
    CONSTRAINT FK_StartPosition_SteamID32 FOREIGN KEY (SteamID32) REFERENCES Players(SteamID32), \
    CONSTRAINT FK_StartPosition_MapID FOREIGN KEY (MapID) REFERENCES Maps(MapID) \
    ON UPDATE CASCADE ON DELETE CASCADE)";

char sql_startpos_upsert[] = "\
REPLACE INTO StartPosition (SteamID32, MapID, X, Y, Z, Angle0, Angle1) \
	VALUES (%d, %d, %f, %f, %f, %f, %f)";

char sql_startpos_get[] = "\
SELECT SteamID32, MapID, X, Y, Z, Angle0, Angle1 \
	FROM \
		StartPosition \
	WHERE \
		SteamID32 = %d AND \
		MapID = %d";