Skip to content

Commit d9a9ff5

Browse files
danmatakizawastocksydan
andauthoredAug 7, 2022
Badge database normalization (#250)
* Database badge PK and FK normalization The following DB changes in the seed data and also the migration badge_info - removal of “id” - badge_filename is new PK badge_affiliation badge_type badge_universe - badge_id replaced with badge_filename, data updated to reflect trade_offered trade_accepted - badge_id replaced with badge_filename, data updated to reflect badges profile_badges - badge_name renamed to badge_filename to reflect content Next steps: 1. update agimus code to remove use of badge_id and badge_name as relational data and reflect the new DB structure * Badge PK/FK normalization common.py: - profile_badges.badge_name is now profile_badges.badge_filename (same data) handlers/xp.py - FoD.png is handed out at welcome, but badges.badge_name is now badges.badge_filename (same data) utils/badge_utils.py - badges.badge_name is now badges.badge_filename (same data) commands/profile.py - db_get_user_badge_names returns the filename under the key ‘badge_filename’ now - profile badge inclusion needed updating too - setting profile badge updated commands/badges.py - updated all the joins and return values to reflect the updated database structure here as well. INSERTS need to use the right name as well, since badges.badge_name is now badges.badge_filename cogs/trade.py - updated all the joins and return values to reflect the updated database structure (badges.badge_name => badges.badge_filename, trade_requested.badge_id => trade_requested.badge_filename, trade_offered.badge_id => trade_offered.badge_filename). Fortunately the queries contain most of the actionable bits, not much python to update, thankfully. * Committing and updating to v1.3.25 * Updating DB query in badges statistics Needed to update the query for badge_name to badge_filename Co-authored-by: Dan Ross <[email protected]>
1 parent 516ca1b commit d9a9ff5

File tree

9 files changed

+287
-107
lines changed

9 files changed

+287
-107
lines changed
 

‎charts/agimus/Chart.yaml

+2-2
Original file line numberDiff line numberDiff line change
@@ -2,5 +2,5 @@ apiVersion: v2
22
name: agimus
33
description: A helm chart for a discord bot that also runs a mysql db
44
type: application
5-
version: v1.4.0
6-
appVersion: v1.4.0
5+
version: v1.4.1
6+
appVersion: v1.4.1

‎cogs/trade.py

+39-39
Original file line numberDiff line numberDiff line change
@@ -30,8 +30,8 @@ async def autocomplete_badges(ctx:discord.AutocompleteContext):
3030
return results
3131

3232
async def _autocomplete_requestor_badges(ctx, requestor_id, requestee_id):
33-
requestor_badges = [b['badge_name'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestor_id)]
34-
requestee_badges = [b['badge_name'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestee_id)]
33+
requestor_badges = [b['badge_filename'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestor_id)] # @TODO improve query to pull badge_name
34+
requestee_badges = [b['badge_filename'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestee_id)] # @TODO improve query to pull badge_name
3535
badge_names = [b for b in requestor_badges if b not in requestee_badges]
3636
if len(badge_names) == 0:
3737
badge_names = ["This user already has all badges that you possess! Use '/trade cancel' to cancel this trade."]
@@ -41,8 +41,8 @@ async def _autocomplete_requestor_badges(ctx, requestor_id, requestee_id):
4141
return [result for result in badge_names if ctx.value.lower() in result.lower()]
4242

4343
async def _autocomplete_requestee_badges(ctx, requestee_id, requestor_id):
44-
requestor_badges = [b['badge_name'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestor_id)]
45-
requestee_badges = [b['badge_name'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestee_id)]
44+
requestor_badges = [b['badge_filename'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestor_id)] # @TODO improve query to pull badge_name
45+
requestee_badges = [b['badge_filename'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(requestee_id)] # @TODO improve query to pull badge name
4646
badge_names = [b for b in requestee_badges if b not in requestor_badges]
4747
if len(badge_names) == 0:
4848
badge_names = ["You already have all badges that this user possesses! Use '/trade cancel' to cancel this trade."]
@@ -403,10 +403,10 @@ async def _cancel_invalid_related_trades(self, active_trade):
403403

404404
async def _requestor_already_has_badges(self, interaction, active_trade, requestor, requestee):
405405
requestor_badges = db_get_user_badge_names(active_trade["requestor_id"])
406-
requestor_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in requestor_badges]
406+
requestor_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in requestor_badges]
407407

408408
trade_requested_badges = db_get_trade_requested_badges(active_trade)
409-
trade_requested_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in trade_requested_badges]
409+
trade_requested_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in trade_requested_badges]
410410

411411
badges_in_trade_requestor_has = [t for t in requestor_badges if t in trade_requested_badges]
412412

@@ -448,10 +448,10 @@ async def _requestor_already_has_badges(self, interaction, active_trade, request
448448

449449
async def _requestee_already_has_badges(self, interaction, active_trade, requestor, requestee):
450450
requestee_badges = db_get_user_badge_names(active_trade["requestee_id"])
451-
requestee_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in requestee_badges]
451+
requestee_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in requestee_badges]
452452

453453
trade_offered_badges = db_get_trade_offered_badges(active_trade)
454-
trade_offered_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in trade_offered_badges]
454+
trade_offered_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in trade_offered_badges]
455455

456456
badges_in_trade_requestee_has = [t for t in requestee_badges if t in trade_offered_badges]
457457

@@ -492,10 +492,10 @@ async def _requestee_already_has_badges(self, interaction, active_trade, request
492492

493493
async def _requestor_still_has_badges(self, interaction, active_trade, requestor, requestee):
494494
requestor_badges = db_get_user_badge_names(active_trade["requestor_id"])
495-
requestor_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in requestor_badges]
495+
requestor_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in requestor_badges]
496496

497497
trade_offered_badges = db_get_trade_offered_badges(active_trade)
498-
trade_offered_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in trade_offered_badges]
498+
trade_offered_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in trade_offered_badges]
499499

500500
badges_in_trade_requestor_has = [t for t in requestor_badges if t in trade_offered_badges]
501501

@@ -536,10 +536,10 @@ async def _requestor_still_has_badges(self, interaction, active_trade, requestor
536536

537537
async def _requestee_still_has_badges(self, interaction, active_trade, requestor, requestee):
538538
requestee_badges = db_get_user_badge_names(active_trade["requestee_id"])
539-
requestee_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in requestee_badges]
539+
requestee_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in requestee_badges]
540540

541541
trade_requested_badges = db_get_trade_requested_badges(active_trade)
542-
trade_requested_badges = [b["badge_name"].replace('_', ' ').replace('.png', '') for b in trade_requested_badges]
542+
trade_requested_badges = [b["badge_filename"].replace('_', ' ').replace('.png', '') for b in trade_requested_badges]
543543

544544
badges_in_trade_requestee_has = [t for t in requestee_badges if t in trade_requested_badges]
545545

@@ -900,7 +900,7 @@ async def _generate_offered_embed_and_image(self, active_trade):
900900
requestor = await self.bot.current_guild.fetch_member(active_trade["requestor_id"])
901901

902902
offered_badges = db_get_trade_offered_badges(active_trade)
903-
offered_badge_filenames = [f"{b['badge_name'].replace(' ', '_')}.png" for b in offered_badges]
903+
offered_badge_filenames = [f"{b['badge_filename']}" for b in offered_badges]
904904
offered_image_id = f"{active_trade['id']}-offered"
905905
offered_image = await generate_badge_trade_showcase(
906906
offered_badge_filenames,
@@ -922,7 +922,7 @@ async def _generate_requested_embed_and_image(self, active_trade):
922922
requestor = await self.bot.current_guild.fetch_member(active_trade["requestor_id"])
923923

924924
requested_badges = db_get_trade_requested_badges(active_trade)
925-
requested_badge_filenames = [f"{b['badge_name'].replace(' ', '_')}.png" for b in requested_badges]
925+
requested_badge_filenames = [f"{b['badge_filename']}" for b in requested_badges]
926926
requested_image_id = f"{active_trade['id']}-requested"
927927
requested_image = await generate_badge_trade_showcase(
928928
requested_badge_filenames,
@@ -1032,11 +1032,11 @@ async def _add_offered_badge_to_trade(self, ctx, active_trade, badge):
10321032
# Don't need to check for active because already done so in propose()
10331033
requestee = await self.bot.current_guild.fetch_member(active_trade["requestee_id"])
10341034
requestee_badges = db_get_user_badge_names(active_trade["requestee_id"])
1035-
requestee_badge_names = [b["badge_name"].replace(".png", "").replace("_", " ") for b in requestee_badges]
1035+
requestee_badge_names = [b["badge_filename"].replace(".png", "").replace("_", " ") for b in requestee_badges]
10361036

10371037
requestor = await self.bot.current_guild.fetch_member(active_trade["requestor_id"])
10381038
requestor_badges = db_get_user_badge_names(active_trade["requestor_id"])
1039-
requestor_badge_names = [b["badge_name"].replace(".png", "").replace("_", " ") for b in requestor_badges]
1039+
requestor_badge_names = [b["badge_filename"].replace(".png", "").replace("_", " ") for b in requestor_badges]
10401040

10411041
logger.info(f"{Fore.CYAN}{requestor.display_name} is looking to offer `{badge}` to {requestee.display_name}.")
10421042

@@ -1107,11 +1107,11 @@ async def _add_requested_badge_to_trade(self, ctx, active_trade, badge):
11071107
# Don't need to check for active because already done so in propose()
11081108
requestee = await self.bot.current_guild.fetch_member(active_trade["requestee_id"])
11091109
requestee_badges = db_get_user_badge_names(active_trade["requestee_id"])
1110-
requestee_badge_names = [b["badge_name"].replace(".png", "").replace("_", " ") for b in requestee_badges]
1110+
requestee_badge_names = [b["badge_filename"].replace(".png", "").replace("_", " ") for b in requestee_badges]
11111111

11121112
requestor = await self.bot.current_guild.fetch_member(active_trade["requestor_id"])
11131113
requestor_badges = db_get_user_badge_names(active_trade["requestor_id"])
1114-
requestor_badge_names = [b["badge_name"].replace(".png", "").replace("_", " ") for b in requestor_badges]
1114+
requestor_badge_names = [b["badge_filename"].replace(".png", "").replace("_", " ") for b in requestor_badges]
11151115

11161116
logger.info(f"{Fore.CYAN}{requestor.display_name} is looking to request `{badge}` from {requestee.display_name}.")
11171117

@@ -1234,10 +1234,10 @@ def db_get_trade_requested_badges(active_trade):
12341234
db = getDB()
12351235
query = db.cursor(dictionary=True)
12361236
sql = '''
1237-
SELECT b_i.badge_name
1237+
SELECT b_i.badge_name, b_i.badge_filename
12381238
FROM badge_info as b_i
12391239
JOIN trade_requested AS t_r
1240-
ON t_r.trade_id = %s AND t_r.badge_id = b_i.id
1240+
ON t_r.trade_id = %s AND t_r.badge_filename = b_i.badge_filename
12411241
'''
12421242
vals = (active_trade_id,)
12431243
query.execute(sql, vals)
@@ -1253,10 +1253,10 @@ def db_get_trade_offered_badges(active_trade):
12531253
db = getDB()
12541254
query = db.cursor(dictionary=True)
12551255
sql = '''
1256-
SELECT b_i.badge_name
1256+
SELECT b_i.badge_name, b_i.badge_filename
12571257
FROM badge_info as b_i
12581258
JOIN trade_offered AS t_o
1259-
ON t_o.trade_id = %s AND t_o.badge_id = b_i.id
1259+
ON t_o.trade_id = %s AND t_o.badge_filename = b_i.badge_filename
12601260
'''
12611261
vals = (active_trade_id,)
12621262
query.execute(sql, vals)
@@ -1272,8 +1272,8 @@ def db_add_badge_to_trade_offer(active_trade, badge_name):
12721272
db = getDB()
12731273
query = db.cursor(dictionary=True)
12741274
sql = '''
1275-
INSERT INTO trade_offered (trade_id, badge_id)
1276-
VALUES (%s, (SELECT id FROM badge_info WHERE badge_name = %s))
1275+
INSERT INTO trade_offered (trade_id, badge_filename)
1276+
VALUES (%s, (SELECT badge_filename FROM badge_info WHERE badge_name = %s))
12771277
'''
12781278
vals = (active_trade_id, badge_name)
12791279
query.execute(sql, vals)
@@ -1288,7 +1288,7 @@ def db_remove_badge_from_trade_offer(active_trade, badge_name):
12881288
query = db.cursor(dictionary=True)
12891289
sql = '''
12901290
DELETE FROM trade_offered
1291-
WHERE trade_id = %s AND badge_id = (SELECT id FROM badge_info WHERE badge_name = %s)
1291+
WHERE trade_id = %s AND badge_filename = (SELECT badge_filename FROM badge_info WHERE badge_name = %s)
12921292
'''
12931293
vals = (active_trade_id, badge_name)
12941294
query.execute(sql, vals)
@@ -1302,8 +1302,8 @@ def db_add_badge_to_trade_request(active_trade, badge_name):
13021302
db = getDB()
13031303
query = db.cursor(dictionary=True)
13041304
sql = '''
1305-
INSERT INTO trade_requested (trade_id, badge_id)
1306-
VALUES (%s, (SELECT id FROM badge_info WHERE badge_name = %s))
1305+
INSERT INTO trade_requested (trade_id, badge_filename)
1306+
VALUES (%s, (SELECT badge_filename FROM badge_info WHERE badge_name = %s))
13071307
'''
13081308
vals = (active_trade_id, badge_name)
13091309
query.execute(sql, vals)
@@ -1318,7 +1318,7 @@ def db_remove_badge_from_trade_request(active_trade, badge_name):
13181318
query = db.cursor(dictionary=True)
13191319
sql = '''
13201320
DELETE FROM trade_requested
1321-
WHERE trade_id = %s AND badge_id = (SELECT id FROM badge_info WHERE badge_name = %s)
1321+
WHERE trade_id = %s AND badge_filename = (SELECT badge_filename FROM badge_info WHERE badge_name = %s)
13221322
'''
13231323
vals = (active_trade_id, badge_name)
13241324
query.execute(sql, vals)
@@ -1404,21 +1404,21 @@ def db_perform_badge_transfer(active_trade):
14041404

14051405
# Transfer Requested Badges to Requestor
14061406
sql = '''
1407-
INSERT INTO badges (user_discord_id, badge_name)
1407+
INSERT INTO badges (user_discord_id, badge_filename)
14081408
SELECT t.requestor_id, b_i.badge_filename
14091409
FROM trades as t
14101410
JOIN badge_info as b_i
14111411
JOIN trade_requested as t_r
1412-
ON t.id = %s AND t_r.trade_id = t.id AND t_r.badge_id = b_i.id
1412+
ON t.id = %s AND t_r.trade_id = t.id AND t_r.badge_filename = b_i.badge_filename
14131413
'''
14141414
vals = (trade_id,)
14151415
query.execute(sql, vals)
14161416

14171417
# Delete Requested Badges from Requestee
14181418
sql = '''
14191419
DELETE b FROM badges b
1420-
JOIN badge_info b_i ON b.badge_name = b_i.badge_filename
1421-
JOIN trade_requested t_r ON t_r.badge_id = b_i.id
1420+
JOIN badge_info b_i ON b.badge_filename = b_i.badge_filename
1421+
JOIN trade_requested t_r ON t_r.badge_filename = b_i.badge_filename
14221422
JOIN trades t ON t_r.trade_id = t.id
14231423
WHERE (t.id = %s AND t.requestee_id = %s AND b.user_discord_id = %s)
14241424
'''
@@ -1427,21 +1427,21 @@ def db_perform_badge_transfer(active_trade):
14271427

14281428
# Transfer Offered Badges to Requestee
14291429
sql = '''
1430-
INSERT INTO badges (user_discord_id, badge_name)
1430+
INSERT INTO badges (user_discord_id, badge_filename)
14311431
SELECT t.requestee_id, b_i.badge_filename
14321432
FROM trades as t
14331433
JOIN badge_info as b_i
14341434
JOIN trade_offered as t_o
1435-
ON t.id = %s AND t_o.trade_id = t.id AND t_o.badge_id = b_i.id
1435+
ON t.id = %s AND t_o.trade_id = t.id AND t_o.badge_filename = b_i.badge_filename
14361436
'''
14371437
vals = (trade_id,)
14381438
query.execute(sql, vals)
14391439

14401440
# Delete Offered Badges from Requestor
14411441
sql = '''
14421442
DELETE b FROM badges b
1443-
JOIN badge_info b_i ON b.badge_name = b_i.badge_filename
1444-
JOIN trade_offered t_o ON t_o.badge_id = b_i.id
1443+
JOIN badge_info b_i ON b.badge_filename = b_i.badge_filename
1444+
JOIN trade_offered t_o ON t_o.badge_filename = b_i.badge_filename
14451445
JOIN trades t ON t_o.trade_id = t.id
14461446
WHERE (t.id = %s AND t.requestor_id = %s AND b.user_discord_id = %s)
14471447
'''
@@ -1490,11 +1490,11 @@ def db_get_related_badge_trades(active_trade):
14901490
LEFT JOIN trade_requested `tr` ON t.id = tr.trade_id
14911491
14921492
INNER JOIN (
1493-
SELECT trade_id, requestor_id, requestee_id, badge_id
1493+
SELECT trade_id, requestor_id, requestee_id, badge_filename
14941494
FROM trade_requested
14951495
INNER JOIN trades ON trade_requested.trade_id = trades.id AND trades.id = %s
14961496
UNION ALL
1497-
SELECT trade_id, requestor_id, requestee_id, badge_id
1497+
SELECT trade_id, requestor_id, requestee_id, badge_filename
14981498
FROM trade_offered
14991499
INNER JOIN trades ON trade_offered.trade_id = trades.id AND trades.id = %s
15001500
) as activeTrade ON 1
@@ -1509,7 +1509,7 @@ def db_get_related_badge_trades(active_trade):
15091509
AND (t.requestor_id IN (activeTrade.requestor_id, activeTrade.requestee_id) OR t.requestee_id IN (activeTrade.requestor_id, activeTrade.requestee_id))
15101510
15111511
-- involves one or more of the badges involved in the active trade
1512-
AND (to.badge_id = activeTrade.badge_id OR tr.badge_id = activeTrade.badge_id)
1512+
AND (to.badge_filename = activeTrade.badge_filename OR tr.badge_filename = activeTrade.badge_filename)
15131513
GROUP BY t.id
15141514
'''
15151515
vals = (active_trade_id, active_trade_id)

‎commands/badges.py

+13-13
Original file line numberDiff line numberDiff line change
@@ -326,7 +326,7 @@ async def badge_statistics(ctx:discord.ApplicationContext):
326326
embed.add_field(name="Total badges collected\non the USS Hood", value=f"{results['total_badges'][0]['count']}", inline=True)
327327
embed.add_field(name=f"{get_emoji('combadge')}", value="⠀", inline=True)
328328
embed.add_field(name="Badges collected today", value=f"{results['badges_today'][0]['count']}", inline=True)
329-
embed.add_field(name="Top 3 most-collected badges", value=str("\n".join(f"{t['badge_name'].replace('_', ' ').replace('.png', '')} ({t['count']})" for t in top_three)), inline=True)
329+
embed.add_field(name="Top 3 most-collected badges", value=str("\n".join(f"{t['badge_filename'].replace('_', ' ').replace('.png', '')} ({t['count']})" for t in top_three)), inline=True)
330330
embed.add_field(name=f"{get_emoji('combadge')}", value="⠀", inline=True)
331331
embed.add_field(name="Top 3 badge collectors", value=str("\n".join(f"{t['name']} ({t['count']})" for t in top_collectors)), inline=True)
332332
await ctx.respond(embed=embed, ephemeral=False)
@@ -472,7 +472,7 @@ def db_get_all_affiliation_badges(affiliation):
472472
sql = '''
473473
SELECT badge_name FROM badge_info b_i
474474
JOIN badge_affiliation AS b_a
475-
ON b_i.id = b_a.badge_id
475+
ON b_i.badge_filename = b_a.badge_filename
476476
WHERE b_a.affiliation_name = %s
477477
'''
478478
vals = (affiliation,)
@@ -493,9 +493,9 @@ def db_get_badges_user_has_from_affiliation(user_id, affiliation):
493493
sql = '''
494494
SELECT b_i.badge_name FROM badges b
495495
JOIN badge_info AS b_i
496-
ON b.badge_name = b_i.badge_filename
496+
ON b.badge_filename = b_i.badge_filename
497497
JOIN badge_affiliation AS b_a
498-
ON b_i.id = b_a.badge_id
498+
ON b_i.badge_filename = b_a.badge_filename
499499
WHERE b.user_discord_id = %s
500500
AND b_a.affiliation_name = %s
501501
'''
@@ -552,7 +552,7 @@ def db_get_badges_user_has_from_franchise(user_id, franchise):
552552
sql = '''
553553
SELECT b_i.badge_name FROM badges b
554554
JOIN badge_info AS b_i
555-
ON b.badge_name = b_i.badge_filename
555+
ON b.badge_filename = b_i.badge_filename
556556
WHERE b.user_discord_id = %s
557557
AND b_i.franchise = %s
558558
'''
@@ -617,7 +617,7 @@ def db_get_badges_user_has_from_time_period(user_id, time_period):
617617
sql = '''
618618
SELECT b_i.badge_name FROM badges b
619619
JOIN badge_info AS b_i
620-
ON b.badge_name = b_i.badge_filename
620+
ON b.badge_filename = b_i.badge_filename
621621
WHERE b.user_discord_id = %s
622622
AND b_i.time_period = %s
623623
'''
@@ -655,7 +655,7 @@ def db_get_all_type_badges(type):
655655
sql = '''
656656
SELECT badge_name FROM badge_info b_i
657657
JOIN badge_type AS b_t
658-
ON b_i.id = b_t.badge_id
658+
ON b_i.badge_filename = b_t.badge_filename
659659
WHERE b_t.type_name = %s
660660
'''
661661
vals = (type,)
@@ -676,9 +676,9 @@ def db_get_badges_user_has_from_type(user_id, type):
676676
sql = '''
677677
SELECT b_i.badge_name FROM badges b
678678
JOIN badge_info AS b_i
679-
ON b.badge_name = b_i.badge_filename
679+
ON b.badge_filename = b_i.badge_filename
680680
JOIN badge_type AS b_t
681-
ON b_i.id = b_t.badge_id
681+
ON b_i.badge_filename = b_t.badge_filename
682682
WHERE b.user_discord_id = %s
683683
AND b_t.type_name = %s
684684
'''
@@ -709,7 +709,7 @@ def give_user_badge(user_discord_id:int):
709709
badge_choice = random.choice(badges)
710710
db = getDB()
711711
query = db.cursor()
712-
sql = "INSERT INTO badges (user_discord_id, badge_name) VALUES (%s, %s)"
712+
sql = "INSERT INTO badges (user_discord_id, badge_filename) VALUES (%s, %s)"
713713
vals = (user_discord_id, badge_choice)
714714
query.execute(sql, vals)
715715
db.commit()
@@ -720,7 +720,7 @@ def give_user_badge(user_discord_id:int):
720720
def give_user_specific_badge(user_discord_id:int, badge_choice:str):
721721
db = getDB()
722722
query = db.cursor()
723-
sql = "INSERT INTO badges (user_discord_id, badge_name) VALUES (%s, %s)"
723+
sql = "INSERT INTO badges (user_discord_id, badge_filename) VALUES (%s, %s)"
724724
vals = (user_discord_id, badge_choice)
725725
query.execute(sql, vals)
726726
db.commit()
@@ -734,7 +734,7 @@ def give_user_specific_badge(user_discord_id:int, badge_choice:str):
734734
def get_user_badges(user_discord_id:int):
735735
db = getDB()
736736
query = db.cursor()
737-
sql = "SELECT badge_name FROM badges WHERE user_discord_id = %s ORDER BY badge_name ASC"
737+
sql = "SELECT badge_filename FROM badges WHERE user_discord_id = %s ORDER BY badge_filename ASC"
738738
vals = (user_discord_id,)
739739
query.execute(sql, vals)
740740
badges = [badge[0] for badge in query.fetchall()]
@@ -745,7 +745,7 @@ def get_user_badges(user_discord_id:int):
745745

746746
def run_badge_stats_queries():
747747
queries = {
748-
"most_collected" : "SELECT badge_name, COUNT(id) as count FROM badges GROUP BY badge_name ORDER BY count DESC LIMIT 3;",
748+
"most_collected" : "SELECT badge_filename, COUNT(id) as count FROM badges GROUP BY badge_filename ORDER BY count DESC LIMIT 3;",
749749
"total_badges" : "SELECT COUNT(id) as count FROM badges;",
750750
"badges_today" : "SELECT COUNT(id) as count FROM badges WHERE time_created > NOW() - INTERVAL 1 DAY;",
751751
"top_collectors" : "SELECT name, COUNT(badges.id) as count FROM users JOIN badges ON users.discord_id = badges.user_discord_id GROUP BY discord_id ORDER BY COUNT(badges.id) DESC LIMIT 3;"

‎commands/profile.py

+14-13
Original file line numberDiff line numberDiff line change
@@ -47,7 +47,7 @@ async def set_tagline(ctx:discord.ApplicationContext, tagline:str):
4747

4848

4949
def user_badges_autocomplete(ctx:discord.AutocompleteContext):
50-
user_badges = [b['badge_name'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(ctx.interaction.user.id)]
50+
user_badges = [b['badge_filename'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(ctx.interaction.user.id)]
5151
if len(user_badges) == 0:
5252
user_badges = ["You don't have any badges yet!"]
5353
user_badges.sort()
@@ -79,7 +79,7 @@ async def set_profile_badge(ctx:discord.ApplicationContext, badge:str):
7979
return
8080

8181
# Check to make sure they own the badge
82-
user_badges = [b['badge_name'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(ctx.author.id)]
82+
user_badges = [b['badge_filename'].replace('_', ' ').replace('.png', '') for b in db_get_user_badge_names(ctx.author.id)]
8383
if badge not in user_badges:
8484
await ctx.respond(embed=discord.Embed(
8585
title="Unable To Set Featured Profile Badge",
@@ -311,26 +311,26 @@ async def profile(ctx:discord.ApplicationContext, public:str):
311311
base_bg.paste(sticker_bg, (406+random.randint(-10,5), 886+random.randint(-3,3)), sticker_bg)
312312

313313
# put badge on
314-
if len(user["badges"]) > 0 and user['badges'][0]['badge_name']:
315-
badge_name = user['badges'][0]['badge_name']
314+
if len(user["badges"]) > 0 and user['badges'][0]['badge_filename']:
315+
badge_filename = user['badges'][0]['badge_filename']
316316
user_badges = db_get_user_badge_names(user['discord_id'])
317-
if badge_name not in [b['badge_name'] for b in user_badges]:
317+
if badge_filename not in [b['badge_filename'] for b in user_badges]:
318318
# Catch if the user had a badge present that they no longer have, if so clear it from the table
319319
db_remove_user_profile_badge(user['discord_id'])
320320
if user["receive_notifications"]:
321321
try:
322322
await ctx.author.send(
323323
embed=discord.Embed(
324324
title="Profile Badge No Longer Present",
325-
description=f"Just a heads up, you had a badge on your profile previously, \"{badge_name.replace('_', ' ').replace('.png', '')}\", which is no longer in your inventory.\n\nYou can set a new featured badge with `/set_profile_badge`!",
325+
description=f"Just a heads up, you had a badge on your profile previously, \"{badge_filename.replace('_', ' ').replace('.png', '')}\", which is no longer in your inventory.\n\nYou can set a new featured badge with `/set_profile_badge`!",
326326
color=discord.Color.red()
327327
)
328328
)
329329
except discord.Forbidden as e:
330330
logger.info(f"Unable to send notification to {ctx.author.display_name} regarding their cleared profile badge, they have their DMs closed.")
331331
else:
332332
# Otherwise go ahead and stamp the badge on their profile PADD
333-
badge_image = Image.open(f"./images/badges/{badge_name}").convert("RGBA").resize((170, 170))
333+
badge_image = Image.open(f"./images/badges/{badge_filename}").convert("RGBA").resize((170, 170))
334334
base_bg.paste(badge_image, (540, 550), badge_image)
335335

336336

@@ -366,8 +366,8 @@ async def profile(ctx:discord.ApplicationContext, public:str):
366366
def db_remove_user_profile_badge(user_id):
367367
db = getDB()
368368
query = db.cursor()
369-
sql = "REPLACE INTO profile_badges (badge_name, user_discord_id) VALUES (%(badge_name)s, %(user_discord_id)s)"
370-
vals = {"badge_name" : "", "user_discord_id" : user_id}
369+
sql = "REPLACE INTO profile_badges (badge_filename, user_discord_id) VALUES (%(badge_filename)s, %(user_discord_id)s)"
370+
vals = {"badge_filename" : "", "user_discord_id" : user_id}
371371
logger.info(f"CLEARING PROFILE BADGE {sql}")
372372
query.execute(sql, vals)
373373
db.commit()
@@ -377,19 +377,20 @@ def db_remove_user_profile_badge(user_id):
377377
def db_add_user_profile_badge(user_id, badge):
378378
db = getDB()
379379
query = db.cursor()
380-
sql = "REPLACE INTO profile_badges (badge_name, user_discord_id) VALUES (%(badge_name)s, %(user_discord_id)s)"
381-
vals = {"badge_name" : badge, "user_discord_id" : user_id}
380+
sql = "REPLACE INTO profile_badges (badge_filename, user_discord_id) VALUES (%(badge_filename)s, %(user_discord_id)s)"
381+
vals = {"badge_filename" : badge, "user_discord_id" : user_id}
382382
logger.info(f"UPDATING PROFILE BADGE {sql} {vals}")
383383
query.execute(sql, vals)
384384
db.commit()
385385
query.close()
386386
db.close()
387387

388-
def db_get_badge_filename_for_badge(badge):
388+
# Given a badge name, retrieves the badge_filename
389+
def db_get_badge_filename_for_badge(badge_name):
389390
db = getDB()
390391
query = db.cursor(dictionary=True)
391392
sql = "SELECT badge_filename FROM badge_info WHERE badge_name = %s"
392-
vals = (badge,)
393+
vals = (badge_name,)
393394
query.execute(sql, vals)
394395
row = query.fetchone()
395396
db.commit()

‎common.py

+1-1
Original file line numberDiff line numberDiff line change
@@ -192,7 +192,7 @@ def get_user(discord_id:int):
192192
query.execute(sql, vals)
193193
user_stickers = query.fetchall()
194194
# get user featured badges
195-
sql = "SELECT badge_name FROM profile_badges WHERE user_discord_id = %s AND badge_name IS NOT NULL"
195+
sql = "SELECT badge_filename FROM profile_badges WHERE user_discord_id = %s AND badge_filename IS NOT NULL"
196196
vals = (discord_id,)
197197
query.execute(sql, vals)
198198
user_badges = query.fetchall()

‎data/seed-db.sql

+35-36
Original file line numberDiff line numberDiff line change
@@ -72,7 +72,7 @@ CREATE TABLE IF NOT EXISTS profile_taglines (
7272
CREATE TABLE IF NOT EXISTS profile_badges (
7373
id int(11) NOT NULL AUTO_INCREMENT,
7474
user_discord_id VARCHAR(64) NOT NULL,
75-
badge_name VARCHAR(255) DEFAULT NULL,
75+
badge_filename VARCHAR(128) DEFAULT NULL,
7676
last_modified TIMESTAMP NOT NULL DEFAULT CURRENT_TIMESTAMP() ON UPDATE CURRENT_TIMESTAMP,
7777
PRIMARY KEY (id),
7878
UNIQUE KEY (user_discord_id)
@@ -92,64 +92,63 @@ CREATE TABLE IF NOT EXISTS trades (
9292
CREATE TABLE IF NOT EXISTS badges (
9393
id int(11) NOT NULL AUTO_INCREMENT,
9494
user_discord_id varchar(64) NOT NULL,
95-
badge_name varchar(128) NOT NULL,
95+
badge_filename varchar(128) NOT NULL,
9696
time_created timestamp NOT NULL DEFAULT current_timestamp(),
9797
PRIMARY KEY (id)
9898
);
99-
CREATE TABLE IF NOT EXISTS badge_info (
100-
id int(11) NOT NULL AUTO_INCREMENT,
101-
badge_name varchar(128) NOT NULL,
102-
badge_filename varchar(128) NOT NULL,
103-
badge_url varchar(256) NOT NULL,
104-
quadrant varchar(128) DEFAULT NULL,
105-
time_period varchar(128) DEFAULT NULL,
106-
franchise varchar(128) DEFAULT NULL,
107-
reference varchar(128) DEFAULT NULL,
108-
PRIMARY KEY (id)
99+
CREATE TABLE IF NOT EXISTS `badge_info` (
100+
`badge_filename` varchar(128) NOT NULL,
101+
`badge_name` varchar(128) NOT NULL,
102+
`badge_url` varchar(256) NOT NULL,
103+
`quadrant` varchar(128) DEFAULT NULL,
104+
`time_period` varchar(128) DEFAULT NULL,
105+
`franchise` varchar(128) DEFAULT NULL,
106+
`reference` varchar(128) DEFAULT NULL,
107+
PRIMARY KEY (`badge_filename`)
109108
);
110109
CREATE TABLE IF NOT EXISTS badge_affiliation (
111-
id int(11) NOT NULL AUTO_INCREMENT,
112-
badge_id int (11) NOT NULL,
113-
affiliation_name varchar(128) NOT NULL,
114-
PRIMARY KEY (id),
115-
FOREIGN KEY (badge_id)
116-
REFERENCES badge_info(id)
110+
`id` int NOT NULL AUTO_INCREMENT,
111+
`badge_filename` varchar(128) NOT NULL,
112+
`affiliation_name` varchar(128) NOT NULL,
113+
PRIMARY KEY (`id`),
114+
KEY `badge_filename` (`badge_filename`),
115+
CONSTRAINT `badge_affiliation_fk_badge_filename` FOREIGN KEY (`badge_filename`) REFERENCES `badge_info` (`badge_filename`)
117116
);
118117
CREATE TABLE IF NOT EXISTS badge_type (
119-
id int(11) NOT NULL AUTO_INCREMENT,
120-
badge_id int (11) NOT NULL,
121-
type_name varchar(128) NOT NULL,
122-
PRIMARY KEY (id),
123-
FOREIGN KEY (badge_id)
124-
REFERENCES badge_info(id)
118+
`id` int NOT NULL AUTO_INCREMENT,
119+
`badge_filename` varchar(128) NOT NULL,
120+
`type_name` varchar(128) NOT NULL,
121+
PRIMARY KEY (`id`),
122+
KEY `badge_filename` (`badge_filename`),
123+
CONSTRAINT `badge_type_fk_badge_filename` FOREIGN KEY (`badge_filename`) REFERENCES `badge_info` (`badge_filename`)
125124
);
126125
CREATE TABLE IF NOT EXISTS badge_universe (
127-
id int(11) NOT NULL AUTO_INCREMENT,
128-
badge_id int (11) NOT NULL,
129-
universe_name varchar(128) NOT NULL,
130-
PRIMARY KEY (id),
131-
FOREIGN KEY (badge_id)
132-
REFERENCES badge_info(id)
126+
`id` int NOT NULL AUTO_INCREMENT,
127+
`badge_filename` varchar(128) NOT NULL,
128+
`universe_name` varchar(128) NOT NULL,
129+
PRIMARY KEY (`id`),
130+
KEY `badge_filename` (`badge_filename`),
131+
CONSTRAINT `badge_universe_fk_badge_filename` FOREIGN KEY (`badge_filename`) REFERENCES `badge_info` (`badge_filename`)
133132
);
134133
CREATE TABLE IF NOT EXISTS trade_offered (
135134
id int(11) NOT NULL AUTO_INCREMENT,
136-
badge_id int(11) NOT NULL,
135+
badge_filename VARCHAR(128) NOT NULL,
137136
trade_id int(11) NOT NULL,
138137
time_created timestamp NOT NULL DEFAULT current_timestamp(),
139138
PRIMARY KEY (id),
140-
FOREIGN KEY (badge_id)
141-
REFERENCES badge_info(id),
139+
FOREIGN KEY (badge_filename)
140+
REFERENCES badge_info(badge_filename),
142141
FOREIGN KEY (trade_id)
143142
REFERENCES trades(id)
144143
);
145144
CREATE TABLE IF NOT EXISTS trade_requested (
146145
id int(11) NOT NULL AUTO_INCREMENT,
147-
badge_id int(11) NOT NULL,
146+
badge_filename VARCHAR(128) NOT NULL,
148147
trade_id int(11) NOT NULL,
149148
time_created timestamp NOT NULL DEFAULT current_timestamp(),
150149
PRIMARY KEY (id),
151-
FOREIGN KEY (badge_id)
152-
REFERENCES badge_info(id),
150+
FOREIGN KEY (badge_filename)
151+
REFERENCES badge_info(badge_filename),
153152
FOREIGN KEY (trade_id)
154153
REFERENCES trades(id)
155154
);

‎handlers/xp.py

+2-2
Original file line numberDiff line numberDiff line change
@@ -257,11 +257,11 @@ async def level_up_user(user:discord.User, level:int):
257257
await send_level_up_message(user, level, badge)
258258

259259
def give_welcome_badge(user_id):
260-
user_badge_names = [b['badge_name'] for b in db_get_user_badge_names(user_id)]
260+
user_badge_names = [b['badge_filename'] for b in db_get_user_badge_names(user_id)]
261261
if "Friends_Of_DeSoto.png" not in user_badge_names:
262262
db = getDB()
263263
query = db.cursor()
264-
sql = "INSERT INTO badges (user_discord_id, badge_name) VALUES (%s, 'Friends_Of_DeSoto.png');"
264+
sql = "INSERT INTO badges (user_discord_id, badge_filename) VALUES (%s, 'Friends_Of_DeSoto.png');"
265265
vals = (user_id,)
266266
query.execute(sql, vals)
267267
db.commit()

‎migrations/v1.4.1.sql

+180
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,180 @@
1+
-- ------------------------------------------------------------
2+
-- BEGIN SECTION A: NEW BADGE METADATA
3+
-- ------------------------------------------------------------
4+
5+
-- Create a new badge_info table, now with blackjack and hookers
6+
-- More specifically, removing id, making badge_filename the PK and moving badge_filename to the top of the table.
7+
CREATE TABLE `badge_info_new` LIKE `badge_info`;
8+
INSERT INTO `badge_info_new` SELECT * FROM badge_info;
9+
ALTER TABLE badge_info_new DROP COLUMN `id`;
10+
ALTER TABLE badge_info_new ADD PRIMARY KEY (`badge_filename`);
11+
ALTER TABLE badge_info_new CHANGE COLUMN badge_name badge_name VARCHAR(128) NOT NULL AFTER badge_filename;
12+
13+
-- Create new badge_affiliation and populate from old one
14+
CREATE TABLE `badge_affiliation_new`
15+
(
16+
`id` int NOT NULL AUTO_INCREMENT,
17+
`badge_filename` varchar(128) NOT NULL,
18+
`affiliation_name` varchar(128) NOT NULL,
19+
PRIMARY KEY (`id`),
20+
KEY `badge_filename` (`badge_filename`),
21+
CONSTRAINT `badge_affiliation_fk_badge_filename` FOREIGN KEY (`badge_filename`) REFERENCES `badge_info_new` (`badge_filename`)
22+
);
23+
24+
INSERT INTO badge_affiliation_new (badge_filename, affiliation_name)
25+
SELECT
26+
badge_info.badge_filename,
27+
badge_affiliation.affiliation_name
28+
FROM badge_info
29+
INNER JOIN badge_affiliation ON badge_info.id = badge_affiliation.badge_id;
30+
31+
-- Create new badge_type and populate from old one
32+
CREATE TABLE `badge_type_new`
33+
(
34+
`id` int NOT NULL AUTO_INCREMENT,
35+
`badge_filename` varchar(128) NOT NULL,
36+
`type_name` varchar(128) NOT NULL,
37+
PRIMARY KEY (`id`),
38+
KEY `badge_filename` (`badge_filename`),
39+
CONSTRAINT `badge_type_fk_badge_filename` FOREIGN KEY (`badge_filename`) REFERENCES `badge_info_new` (`badge_filename`)
40+
);
41+
42+
INSERT INTO badge_type_new (badge_filename, type_name)
43+
SELECT
44+
badge_info.badge_filename,
45+
badge_type.type_name
46+
FROM badge_info
47+
INNER JOIN badge_type ON badge_info.id = badge_type.badge_id;
48+
49+
-- Create new badge universe and populate from old one
50+
CREATE TABLE `badge_universe_new`
51+
(
52+
`id` int NOT NULL AUTO_INCREMENT,
53+
`badge_filename` varchar(128) NOT NULL,
54+
`universe_name` varchar(128) NOT NULL,
55+
PRIMARY KEY (`id`),
56+
KEY `badge_filename` (`badge_filename`),
57+
CONSTRAINT `badge_universe_fk_badge_filename` FOREIGN KEY (`badge_filename`) REFERENCES `badge_info_new` (`badge_filename`)
58+
);
59+
60+
INSERT INTO badge_universe_new (badge_filename, universe_name)
61+
SELECT
62+
badge_info.badge_filename,
63+
badge_universe.universe_name
64+
FROM badge_info
65+
INNER JOIN badge_universe ON badge_info.id = badge_universe.badge_id;
66+
67+
68+
-- ------------------------------------------------------------
69+
-- END SECTION A: NEW BADGE METADATA
70+
-- ------------------------------------------------------------
71+
72+
-- ------------------------------------------------------------
73+
-- BEGIN SECTION B: UPDATE BADGE REFERENCES
74+
-- ------------------------------------------------------------
75+
76+
-- trade_offered
77+
CREATE TABLE IF NOT EXISTS trade_offered_new
78+
(
79+
id int(11) NOT NULL AUTO_INCREMENT,
80+
badge_filename VARCHAR(128) NOT NULL,
81+
trade_id int(11) NOT NULL,
82+
time_created timestamp NOT NULL DEFAULT current_timestamp(),
83+
PRIMARY KEY (id),
84+
FOREIGN KEY (badge_filename)
85+
REFERENCES badge_info_new (badge_filename),
86+
FOREIGN KEY (trade_id)
87+
REFERENCES trades (id)
88+
);
89+
INSERT INTO trade_offered_new (id, badge_filename, trade_id, time_created)
90+
SELECT
91+
trade_offered.id,
92+
badge_info.badge_filename,
93+
trade_offered.trade_id,
94+
trade_offered.time_created
95+
FROM trade_offered
96+
INNER JOIN badge_info ON trade_offered.badge_id = badge_info.id;
97+
98+
-- trade_requested
99+
CREATE TABLE IF NOT EXISTS trade_requested_new
100+
(
101+
id int(11) NOT NULL AUTO_INCREMENT,
102+
badge_filename VARCHAR(128) NOT NULL,
103+
trade_id int(11) NOT NULL,
104+
time_created timestamp NOT NULL DEFAULT current_timestamp(),
105+
PRIMARY KEY (id),
106+
FOREIGN KEY (badge_filename)
107+
REFERENCES badge_info_new (badge_filename),
108+
FOREIGN KEY (trade_id)
109+
REFERENCES trades (id)
110+
);
111+
INSERT INTO trade_requested_new (id, badge_filename, trade_id, time_created)
112+
SELECT
113+
trade_requested.id,
114+
badge_info.badge_filename,
115+
trade_requested.trade_id,
116+
trade_requested.time_created
117+
FROM trade_requested
118+
INNER JOIN badge_info ON trade_requested.badge_id = badge_info.id;
119+
120+
-- badges
121+
CREATE TABLE `badges_new`
122+
(
123+
`id` int NOT NULL AUTO_INCREMENT,
124+
`user_discord_id` varchar(64) NOT NULL,
125+
`badge_filename` varchar(128) NOT NULL,
126+
`time_created` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
127+
PRIMARY KEY (`id`)
128+
);
129+
INSERT INTO badges_new (id, user_discord_id, badge_filename, time_created) SELECT id, user_discord_id, badge_name as badge_filename, time_created FROM badges;
130+
131+
-- profile_badges;
132+
CREATE TABLE `profile_badges_new`
133+
(
134+
`id` int NOT NULL AUTO_INCREMENT,
135+
`user_discord_id` varchar(64) NOT NULL,
136+
`badge_filename` varchar(128) DEFAULT NULL,
137+
`last_modified` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
138+
PRIMARY KEY (`id`),
139+
UNIQUE KEY `user_discord_id` (`user_discord_id`)
140+
);
141+
INSERT INTO profile_badges_new (id, user_discord_id, badge_filename, last_modified) SELECT id, user_discord_id, badge_name, last_modified FROM profile_badges;
142+
143+
-- @TODO profile_badges should use badge_filename, not badge_name
144+
145+
146+
-- @TODO swap table names
147+
148+
-- ------------------------------------------------------------
149+
-- END SECTION B: UPDATE BADGE REFERENCES
150+
-- ------------------------------------------------------------
151+
152+
-- ------------------------------------------------------------
153+
-- START SECTION C: CLEANUP
154+
-- ------------------------------------------------------------
155+
156+
-- Swap tables so previous ones are now "_old"
157+
RENAME TABLE badge_info to badge_info_old, badge_info_new to badge_info;
158+
RENAME TABLE badge_affiliation to badge_affiliation_old, badge_affiliation_new to badge_affiliation;
159+
RENAME TABLE badge_type to badge_type_old, badge_type_new to badge_type;
160+
RENAME TABLE badge_universe to badge_universe_old, badge_universe_new to badge_universe;
161+
162+
RENAME TABLE badges to badges_old, badges_new to badges;
163+
RENAME TABLE profile_badges to profile_badges_old, profile_badges_new to profile_badges;
164+
RENAME TABLE trade_offered to trade_offered_old, trade_offered_new to trade_offered;
165+
RENAME TABLE trade_requested to trade_requested_old, trade_requested_new to trade_requested;
166+
167+
168+
-- When you're happy, then uncomment and execute the following lines to remove the old tables.
169+
DROP TABLE profile_badges_old;
170+
DROP TABLE trade_offered_old;
171+
DROP TABLE trade_requested_old;
172+
DROP TABLE badges_old;
173+
DROP TABLE badge_affiliation_old;
174+
DROP TABLE badge_type_old;
175+
DROP TABLE badge_universe_old;
176+
DROP TABLE badge_info_old;
177+
178+
-- ------------------------------------------------------------
179+
-- END SECTION C: CLEANUP
180+
-- ------------------------------------------------------------

‎utils/badge_utils.py

+1-1
Original file line numberDiff line numberDiff line change
@@ -300,7 +300,7 @@ def db_get_badge_count_for_user(user_id):
300300
def db_get_user_badge_names(user_id):
301301
db = getDB()
302302
query = db.cursor(dictionary=True)
303-
sql = "SELECT badge_name FROM badges WHERE user_discord_id = %s"
303+
sql = "SELECT badge_filename FROM badges WHERE user_discord_id = %s"
304304
vals = (user_id,)
305305
query.execute(sql, vals)
306306
badge_names = query.fetchall()

0 commit comments

Comments
 (0)
Please sign in to comment.