Skip to content

Commit

Permalink
Fixed SQL file to merge xxx_loot_template tables into single table (#184
Browse files Browse the repository at this point in the history
)

* Fixed SQL file to merge xxx_loot_template tables into single loot_template table. Added Python script to do some basic integrity checks.

* Changed to MySQLdb connector, so it's consistent with other tools.

---------

Co-authored-by: Ginger Gibbons <darren.staples@virgin.net>
  • Loading branch information
GingerGibbons and Ginger Gibbons authored Feb 8, 2023
1 parent 3b8739a commit bd80536
Show file tree
Hide file tree
Showing 3 changed files with 144 additions and 0 deletions.
16 changes: 16 additions & 0 deletions contrib/lootTemplateMergeSql/README.txt
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
#
# This code is part of MaNGOS. Contributor & Copyright details are in AUTHORS/THANKS.
#

Contents
loot_template_merge.sql - MySQL commands to merge all the xxx_loot_template tables into a single loot_template table.
A new field, lootTypeId is added to differentiate entries from the various source tables.
Execute with: mysql -h localhost -u mangos --password=mangos -D mangos2 < loot_template_merge.sql
test_loot_template_merge.py - Python script to run some basic queries on the xxx_loot_template and loot_template tables to verify
that the merge was correct.

Requirements:
* Python 3.10 (at least tested with this version)
* The MySQLdb module

Backup your data, before you change anything!
83 changes: 83 additions & 0 deletions contrib/lootTemplateMergeSql/loot_template_merge.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,83 @@
/*Table structure for table `loot_template` */

DROP TABLE IF EXISTS `loot_template`;

CREATE TABLE `loot_template` (
`entry` MEDIUMINT(8) UNSIGNED NOT NULL DEFAULT '0' COMMENT 'id of the loot',
`lootTypeId` TINYINT(2) UNSIGNED NOT NULL COMMENT 'lootType of the loot 1-12',
`item` MEDIUMINT(8) UNSIGNED NOT NULL DEFAULT '0' COMMENT 'itemid of the item',
`ChanceOrQuestChance` FLOAT NOT NULL DEFAULT '100',
`groupid` TINYINT(3) UNSIGNED NOT NULL DEFAULT '0',
`mincountOrRef` MEDIUMINT(9) NOT NULL DEFAULT '1',
`maxcount` TINYINT(3) UNSIGNED NOT NULL DEFAULT '1',
`condition_id` MEDIUMINT(8) UNSIGNED NOT NULL DEFAULT '0',
PRIMARY KEY (`entry`,`lootTypeId`,`item`),
KEY `entry` (`entry`,`lootTypeId`)
) ENGINE=MYISAM DEFAULT CHARSET=utf8 ROW_FORMAT=DYNAMIC;


/*
Import the following tables into loot_table, filling in the new lootTypeId field:
1 = creature_loot_template
2 = disenchant_loot_template
3 = fishing_loot_template
4 = gameobject_loot_template
5 = item_loot_template
6 = mail_loot_template
7 = milling_loot_template -- milling_loot_template Added in WOTLK
8 = pickpocketing_loot_template
9 = prospecting_loot_template -- prospecting_loot_template Added in TBC
10 = reference_loot_template
11 = skinning_loot_template
12 = spell_loot_template -- spell_loot_template Added in WOTLK
*/

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 1, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `creature_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 2, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `disenchant_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 3, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `fishing_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 4, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `gameobject_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 5, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `item_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 6, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `mail_loot_template`;

-- milling_loot_template Added in WOTLK
INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 7, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `milling_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 8, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `pickpocketing_loot_template`;

-- prospecting_loot_template Added in TBC
INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 9, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `prospecting_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 10, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `reference_loot_template`;

INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 11, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `skinning_loot_template`;

-- spell_loot_template Added in WOTLK
INSERT INTO `loot_template` (`entry`, lootTypeId, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id`)
SELECT `entry`, 12, `item`, `ChanceOrQuestChance`, `groupid`, `mincountOrRef`, `maxcount`, `condition_id` FROM `spell_loot_template`;


/*
SELECT * FROM creature_loot_template WHERE entry=3; -- Exec 0.007s Total: 0.029s 57 Rows
SELECT * FROM creature_loot_template WHERE entry=61; -- Exec 0.015s Total: 0.069s 57 Rows
SELECT * FROM loot_template WHERE entry=61 AND loottypeid=1; -- Exec 0.014s Total: 0.066s 57 Rows
SELECT * FROM creature_loot_template WHERE entry=61 AND item=2406; -- Exec 0.014s Total: 0.065s 1 Rows
SELECT * FROM loot_template WHERE entry=61 AND loottypeid=1 AND item=2406; -- Exec 0.014s Total: 0.064s 1 Rows
*/
45 changes: 45 additions & 0 deletions contrib/lootTemplateMergeSql/test_loot_template_merge.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
# Script to test loot template merge
import MySQLdb

# MySQL server
server = "localhost"
# Database
database = "mangos2"
# Username
username = "mangos"
# Password
password = "mangos"

# Open database connection
db = MySQLdb.connect(host=server, user=username, password=password, database=database)
cur = db.cursor()

loot_tables = ["creature_loot_template", "disenchant_loot_template", "fishing_loot_template", "gameobject_loot_template",
"item_loot_template", "mail_loot_template", "milling_loot_template", "pickpocketing_loot_template",
"prospecting_loot_template", "reference_loot_template", "skinning_loot_template", "spell_loot_template"]

lootTypeId = 1
origTotal = 0
with db:
for loot_table in loot_tables:
# Check that the correct number of rows from the original table have been merged into loot_template
cur.execute(db.escape_string("SELECT COUNT(entry) FROM `%s`" % loot_table))
origCount = cur.fetchone()[0]
cur.execute(db.escape_string("SELECT COUNT(entry) FROM loot_template WHERE lootTypeId=%s" % lootTypeId))
mergedCount = cur.fetchone()[0]
if origCount != mergedCount:
print("Mismatch for table "+loot_table)
print(loot_table + " original count = " + str(origCount))
print("loot_template merged count = " + str(mergedCount))
exit()
origTotal = origTotal + origCount
lootTypeId = lootTypeId + 1

# Check that the total number of rows matches the sum of all the original tables
cur.execute(db.escape_string("SELECT COUNT(entry) FROM loot_template"))
mergedTotal = cur.fetchone()[0]
if origTotal != mergedTotal:
print("Mismatch in total no. of rows!")
exit()

print("No errors found!")

0 comments on commit bd80536

Please sign in to comment.