-
Notifications
You must be signed in to change notification settings - Fork 304
/
Copy pathcreate_tables.sql
473 lines (439 loc) · 12.2 KB
/
create_tables.sql
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
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
CREATE EXTENSION IF NOT EXISTS pg_trgm;
CREATE EXTENSION IF NOT EXISTS tsm_system_rows;
CREATE TABLE IF NOT EXISTS matches (
match_id bigint PRIMARY KEY,
match_seq_num bigint,
radiant_win boolean,
start_time integer,
duration integer,
tower_status_radiant integer,
tower_status_dire integer,
barracks_status_radiant integer,
barracks_status_dire integer,
cluster integer,
first_blood_time integer,
lobby_type integer,
human_players integer,
leagueid integer,
positive_votes integer,
negative_votes integer,
game_mode integer,
engine integer,
radiant_score integer,
dire_score integer,
picks_bans json[],
radiant_team_id integer,
dire_team_id integer,
radiant_team_name varchar(255),
dire_team_name varchar(255),
radiant_team_complete smallint,
dire_team_complete smallint,
radiant_captain bigint,
dire_captain bigint,
chat json[],
objectives json[],
radiant_gold_adv integer[],
radiant_xp_adv integer[],
teamfights json[],
draft_timings json[],
version integer,
cosmetics json,
series_id integer,
series_type integer,
replay_salt integer
);
CREATE INDEX IF NOT EXISTS matches_leagueid_idx on matches(leagueid) WHERE leagueid > 0;
CREATE INDEX IF NOT EXISTS matches_start_time_idx on matches(start_time);
CREATE TABLE IF NOT EXISTS player_matches (
PRIMARY KEY(match_id, player_slot),
match_id bigint REFERENCES matches(match_id) ON DELETE CASCADE,
account_id bigint,
player_slot integer,
hero_id integer,
item_0 integer,
item_1 integer,
item_2 integer,
item_3 integer,
item_4 integer,
item_5 integer,
item_neutral integer,
backpack_0 integer,
backpack_1 integer,
backpack_2 integer,
backpack_3 integer,
kills integer,
deaths integer,
assists integer,
leaver_status integer,
gold integer,
last_hits integer,
denies integer,
gold_per_min integer,
xp_per_min integer,
gold_spent integer,
hero_damage integer,
tower_damage bigint,
hero_healing bigint,
level integer,
--ability_upgrades json[],
additional_units json[],
--parsed fields below
stuns real,
max_hero_hit json,
times integer[],
gold_t integer[],
lh_t integer[],
dn_t integer[],
xp_t integer[],
obs_log json[],
sen_log json[],
obs_left_log json[],
sen_left_log json[],
purchase_log json[],
kills_log json[],
buyback_log json[],
runes_log json[],
connection_log json[],
lane_pos json,
obs json,
sen json,
actions json,
pings json,
purchase json,
gold_reasons json,
xp_reasons json,
killed json,
item_uses json,
ability_uses json,
ability_targets json,
damage_targets json,
hero_hits json,
damage json,
damage_taken json,
damage_inflictor json,
runes json,
killed_by json,
kill_streaks json,
multi_kills json,
life_state json,
damage_inflictor_received json,
obs_placed int,
sen_placed int,
creeps_stacked int,
camps_stacked int,
rune_pickups int,
ability_upgrades_arr integer[],
party_id int,
permanent_buffs json[],
hero_variant int,
lane int,
lane_role int,
is_roaming boolean,
firstblood_claimed int,
teamfight_participation real,
towers_killed int,
roshans_killed int,
observers_placed int,
party_size int,
net_worth int,
neutral_tokens_log json[],
neutral_item_history json[]
);
CREATE INDEX IF NOT EXISTS player_matches_account_id_idx on player_matches(account_id) WHERE account_id IS NOT NULL;
CREATE INDEX IF NOT EXISTS player_matches_hero_id_idx on player_matches(hero_id);
CREATE TABLE IF NOT EXISTS players (
account_id bigint PRIMARY KEY,
steamid varchar(32),
avatar varchar(255),
avatarmedium varchar(255),
avatarfull varchar(255),
profileurl varchar(255),
personaname varchar(255),
plus boolean DEFAULT false,
last_login timestamp with time zone,
full_history_time timestamp with time zone,
cheese integer DEFAULT 0,
fh_unavailable boolean,
loccountrycode varchar(2),
last_match_time timestamp with time zone
/*
"communityvisibilitystate" : 3,
"lastlogoff" : 1426020853,
"loccityid" : 44807,
"locstatecode" : "16",
"personastate" : 0,
"personastateflags" : 0,
"primaryclanid" : "103582791433775490",
"profilestate" : 1,
"realname" : "Alper",
"timecreated" : 1332289262,
*/
);
CREATE INDEX IF NOT EXISTS players_cheese_idx on players(cheese) WHERE cheese IS NOT NULL AND cheese > 0;
CREATE INDEX IF NOT EXISTS players_personaname_idx_gin ON players USING GIN(personaname gin_trgm_ops);
CREATE INDEX IF NOT EXISTS players_personaname_idx_gist ON players USING GIST(personaname gist_trgm_ops);
CREATE TABLE IF NOT EXISTS player_ratings (
PRIMARY KEY(account_id, time),
account_id bigint,
match_id bigint,
solo_competitive_rank integer,
competitive_rank integer,
time timestamp with time zone
);
CREATE TABLE IF NOT EXISTS subscriptions (
PRIMARY KEY(customer_id),
account_id bigint REFERENCES players(account_id) ON DELETE CASCADE,
customer_id varchar(255),
amount int,
active_until date
);
CREATE INDEX IF NOT EXISTS subscriptions_account_id_idx on subscriptions(account_id);
CREATE INDEX IF NOT EXISTS subscriptions_customer_id_idx on subscriptions(customer_id);
CREATE TABLE IF NOT EXISTS webhooks (
PRIMARY KEY(hook_id),
hook_id uuid UNIQUE,
account_id bigint,
url text NOT NULL,
subscriptions jsonb NOT NULL
);
CREATE INDEX IF NOT EXISTS webhooks_account_id_idx on webhooks(account_id);
CREATE TABLE IF NOT EXISTS api_keys (
PRIMARY KEY(account_id, subscription_id),
account_id bigint NOT NULL,
api_key uuid UNIQUE,
customer_id text NOT NULL,
subscription_id text NOT NULL UNIQUE,
is_canceled boolean
);
CREATE TABLE IF NOT EXISTS api_key_usage (
PRIMARY KEY(account_id, api_key, ip, timestamp),
account_id bigint,
customer_id text,
api_key uuid REFERENCES api_keys(api_key),
usage_count bigint,
ip text,
timestamp timestamp default current_timestamp
);
CREATE INDEX IF NOT EXISTS api_keys_usage_account_id_idx on api_key_usage(account_id);
CREATE INDEX IF NOT EXISTS api_keys_usage_timestamp_idx on api_key_usage(timestamp);
CREATE TABLE IF NOT EXISTS user_usage (
account_id bigint,
ip text,
usage_count bigint,
timestamp timestamp default current_timestamp
);
CREATE INDEX IF NOT EXISTS user_usage_account_id_idx on user_usage(account_id);
CREATE INDEX IF NOT EXISTS user_usage_timestamp_idx on user_usage(timestamp);
CREATE UNIQUE INDEX IF NOT EXISTS user_usage_unique_idx on user_usage(account_id, ip, timestamp);
CREATE TABLE IF NOT EXISTS notable_players (
account_id bigint PRIMARY KEY,
name varchar(255),
country_code varchar(2),
fantasy_role int,
team_id int,
team_name varchar(255),
team_tag varchar(255),
is_locked boolean,
is_pro boolean,
locked_until integer
);
CREATE TABLE IF NOT EXISTS picks_bans(
match_id bigint REFERENCES matches(match_id) ON DELETE CASCADE,
is_pick boolean,
hero_id int,
team smallint,
ord smallint,
PRIMARY KEY (match_id, ord)
);
CREATE TABLE IF NOT EXISTS leagues(
leagueid bigint PRIMARY KEY,
ticket varchar(255),
banner varchar(255),
tier varchar(255),
name varchar(255)
);
CREATE TABLE IF NOT EXISTS teams(
team_id bigint PRIMARY KEY,
name varchar(255),
tag varchar(255),
logo_url text
);
CREATE TABLE IF NOT EXISTS heroes(
id int PRIMARY KEY,
name text,
localized_name text,
primary_attr text,
attack_type text,
roles text[]
);
CREATE TABLE IF NOT EXISTS match_patch(
match_id bigint REFERENCES matches(match_id) ON DELETE CASCADE PRIMARY KEY,
patch text
);
CREATE TABLE IF NOT EXISTS team_match(
team_id bigint,
match_id bigint REFERENCES matches(match_id) ON DELETE CASCADE,
radiant boolean,
PRIMARY KEY(team_id, match_id)
);
CREATE TABLE IF NOT EXISTS items(
id int PRIMARY KEY,
name text,
cost int,
secret_shop smallint,
side_shop smallint,
recipe smallint,
localized_name text
);
CREATE TABLE IF NOT EXISTS cosmetics(
item_id int PRIMARY KEY,
name text,
prefab text,
creation_date timestamp with time zone,
image_inventory text,
image_path text,
item_description text,
item_name text,
item_rarity text,
item_type_name text,
used_by_heroes text
);
CREATE TABLE IF NOT EXISTS public_matches (
match_id bigint PRIMARY KEY,
match_seq_num bigint,
radiant_win boolean,
start_time integer,
duration integer,
lobby_type integer,
game_mode integer,
avg_rank_tier double precision,
num_rank_tier integer,
cluster integer,
radiant_team integer[],
dire_team integer[]
);
CREATE INDEX IF NOT EXISTS public_matches_start_time_idx on public_matches(start_time);
CREATE INDEX IF NOT EXISTS public_matches_avg_rank_tier_idx on public_matches(avg_rank_tier) WHERE avg_rank_tier IS NOT NULL;
CREATE TABLE IF NOT EXISTS team_rating (
PRIMARY KEY(team_id),
team_id bigint,
rating real,
wins int,
losses int,
last_match_time bigint
);
CREATE INDEX IF NOT EXISTS team_rating_rating_idx ON team_rating(rating);
CREATE TABLE IF NOT EXISTS hero_ranking (
PRIMARY KEY (account_id, hero_id),
account_id bigint,
hero_id int,
score double precision
);
CREATE INDEX IF NOT EXISTS hero_ranking_hero_id_score_idx ON hero_ranking(hero_id, score);
CREATE TABLE IF NOT EXISTS queue (
PRIMARY KEY (id),
id bigserial,
type text,
timestamp timestamp with time zone,
attempts int,
data json,
next_attempt_time timestamp with time zone,
priority int
);
CREATE INDEX IF NOT EXISTS queue_priority_id_idx on queue(priority, id);
CREATE TABLE IF NOT EXISTS solo_competitive_rank (
PRIMARY KEY (account_id),
account_id bigint,
rating int
);
CREATE TABLE IF NOT EXISTS competitive_rank (
PRIMARY KEY (account_id),
account_id bigint,
rating int
);
CREATE TABLE IF NOT EXISTS rank_tier (
PRIMARY KEY (account_id),
account_id bigint,
rating int
);
CREATE INDEX IF NOT EXISTS rank_tier_rating_idx ON rank_tier(rating);
CREATE TABLE IF NOT EXISTS leaderboard_rank (
PRIMARY KEY (account_id),
account_id bigint,
rating int
);
CREATE TABLE IF NOT EXISTS scenarios (
hero_id smallint,
item text,
time integer,
lane_role smallint,
games bigint DEFAULT 1,
wins bigint,
epoch_week integer,
UNIQUE (hero_id, item, time, epoch_week),
UNIQUE (hero_id, lane_role, time, epoch_week)
);
CREATE TABLE IF NOT EXISTS team_scenarios (
scenario text,
is_radiant boolean,
region smallint,
games bigint DEFAULT 1,
wins bigint,
epoch_week integer,
UNIQUE (scenario, is_radiant, region, epoch_week)
);
CREATE TABLE IF NOT EXISTS hero_search (
PRIMARY KEY (match_id),
match_id bigint,
teamA int[],
teamB int[],
teamAWin boolean,
start_time int
);
CREATE INDEX IF NOT EXISTS hero_search_teamA_idx_gin ON hero_search USING GIN(teamA);
CREATE INDEX IF NOT EXISTS hero_search_teamB_idx_gin ON hero_search USING GIN(teamB);
CREATE TABLE IF NOT EXISTS parsed_matches (
PRIMARY KEY (match_id),
match_id bigint,
is_archived boolean
);
CREATE INDEX IF NOT EXISTS parsed_matches_is_archived_idx ON parsed_matches(is_archived);
CREATE TABLE IF NOT EXISTS subscriber (
PRIMARY KEY (account_id),
account_id bigint,
customer_id varchar(255),
status varchar(100)
);
CREATE TABLE IF NOT EXISTS last_seq_num (
PRIMARY KEY (match_seq_num),
match_seq_num bigint
);
--Stores matches that the user has played in but might be previously anonymous in API data
--We might want to fetch the data from our own DB and fill player_caches
CREATE TABLE IF NOT EXISTS player_match_history(
PRIMARY KEY (match_id, account_id),
account_id bigint,
match_id bigint,
player_slot integer,
retries integer
);
CREATE INDEX IF NOT EXISTS player_match_history_retries_idx ON player_match_history(retries ASC NULLS FIRST);
DO $$
BEGIN
IF EXISTS (SELECT 1 FROM pg_roles WHERE rolname = 'readonly') THEN
GRANT SELECT ON matches TO readonly;
GRANT SELECT ON player_matches TO readonly;
GRANT SELECT ON heroes TO readonly;
GRANT SELECT ON leagues TO readonly;
GRANT SELECT ON items TO readonly;
GRANT SELECT ON teams TO readonly;
GRANT SELECT ON team_match TO readonly;
GRANT SELECT ON match_patch TO readonly;
GRANT SELECT ON picks_bans TO readonly;
GRANT SELECT ON notable_players TO readonly;
GRANT SELECT ON public_matches TO readonly;
GRANT SELECT ON players TO readonly;
GRANT SELECT ON team_rating TO readonly;
END IF;
END
$$;