add colors to modeling query, no change to gql yet

This updates the MySQL procedure to get the important special colors, but keeps the GQL behavior the same by only filtering to Blue. Just an incremental step before changing the behavior, to make sure I've gotten it right so far!

Snapshots significantly updated, but, from scanning it, I think that's expected changes from actual modeling progress. Hooray!
This commit is contained in:
Emi Matchu 2020-09-15 02:38:23 -07:00
parent 351b9a88bd
commit 32822b250d
5 changed files with 1454 additions and 2824 deletions

View file

@ -31,10 +31,10 @@ GRANT SELECT ON users TO impress2020;
DELIMITER $$ DELIMITER $$
DROP PROCEDURE IF EXISTS GetItemsThatNeedModels$$ DROP PROCEDURE IF EXISTS GetItemsThatNeedModelsV2$$
CREATE PROCEDURE GetItemsThatNeedModels() CREATE PROCEDURE GetItemsThatNeedModelsV2()
BEGIN BEGIN
SELECT items.id, SELECT pet_types.color_id AS color_id, items.id AS item_id,
GROUP_CONCAT(DISTINCT pet_types.species_id ORDER BY pet_types.species_id) GROUP_CONCAT(DISTINCT pet_types.species_id ORDER BY pet_types.species_id)
AS modeled_species_ids, AS modeled_species_ids,
-- Vandagyre was added on 2014-11-14, so we add some buffer here. -- Vandagyre was added on 2014-11-14, so we add some buffer here.
@ -49,23 +49,29 @@ BEGIN
INNER JOIN pet_types INNER JOIN pet_types
ON pet_types.body_id = swf_assets.body_id ON pet_types.body_id = swf_assets.body_id
WHERE WHERE
pet_types.color_id = "8" pet_types.color_id IN (
8, -- Blue (Standard)
6, -- Baby
44, -- Maraquan
46, -- Mutant
92 -- 8-bit
)
AND items.modeling_status_hint IS NULL AND items.modeling_status_hint IS NULL
GROUP BY items.id GROUP BY color_id, item_id
HAVING HAVING
NOT ( NOT (
-- No species (either an All Bodies item, or a Capsule type thing)
count(DISTINCT pet_types.species_id) = 0
-- Single species (probably just their item) -- Single species (probably just their item)
count(DISTINCT pet_types.species_id) = 1 OR count(DISTINCT pet_types.species_id) = 1
-- All species modeled -- All species modeled
OR modeled_species_ids = "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" OR count(DISTINCT pet_types.species_id) = 55
-- All species modeled except Vandagyre, for items that don't support it -- All species modeled except Vandagyre, for items that don't support it
OR (NOT supports_vandagyre AND modeled_species_ids = "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") OR (NOT supports_vandagyre AND modeled_species_ids = "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")
-- No species (either an All Bodies item, or a Capsule type thing)
OR modeled_species_ids = ""
) )
ORDER BY items.id; ORDER BY color_id, item_id;
END$$ END$$
GRANT EXECUTE ON PROCEDURE GetItemsThatNeedModels TO impress2020$$ GRANT EXECUTE ON PROCEDURE GetItemsThatNeedModelsV2 TO impress2020$$
-- This procedure is a performance optimization! We want the page to always be -- This procedure is a performance optimization! We want the page to always be
-- up-to-date, but we want to avoid re-running this query if modeling data -- up-to-date, but we want to avoid re-running this query if modeling data
@ -74,8 +80,8 @@ GRANT EXECUTE ON PROCEDURE GetItemsThatNeedModels TO impress2020$$
-- queries are a bottleneck, so I bundled up that logic into this single -- queries are a bottleneck, so I bundled up that logic into this single
-- procedure that can run on the database! That way, it's just one network -- procedure that can run on the database! That way, it's just one network
-- round-trip instead of two, which makes a noticeable difference in our stack. -- round-trip instead of two, which makes a noticeable difference in our stack.
DROP PROCEDURE IF EXISTS GetItemsThatNeedModelsIfNotCached$$ DROP PROCEDURE IF EXISTS GetItemsThatNeedModelsIfNotCachedV2$$
CREATE PROCEDURE GetItemsThatNeedModelsIfNotCached( CREATE PROCEDURE GetItemsThatNeedModelsIfNotCachedV2(
IN last_known_update TIMESTAMP, IN last_known_update TIMESTAMP,
OUT last_actual_update TIMESTAMP OUT last_actual_update TIMESTAMP
) )
@ -84,9 +90,9 @@ BEGIN
(SELECT created_at FROM contributions ORDER BY id DESC LIMIT 1); (SELECT created_at FROM contributions ORDER BY id DESC LIMIT 1);
IF last_known_update < last_actual_update THEN IF last_known_update < last_actual_update THEN
CALL GetItemsThatNeedModels(); CALL GetItemsThatNeedModelsV2();
END IF; END IF;
END$$ END$$
GRANT EXECUTE ON PROCEDURE GetItemsThatNeedModelsIfNotCached TO impress2020$$ GRANT EXECUTE ON PROCEDURE GetItemsThatNeedModelsIfNotCachedV2 TO impress2020$$
DELIMITER ; DELIMITER ;

View file

@ -254,9 +254,12 @@ const buildItemsThatNeedModelsLoader = (db) =>
// only run the query if modeling data has been changed since the timestamp // only run the query if modeling data has been changed since the timestamp
// we provide; otherwise, it skips the query and returns no rows, which is // we provide; otherwise, it skips the query and returns no rows, which is
// much faster! (The query takes a few seconds to run.) // much faster! (The query takes a few seconds to run.)
//
// NOTE: This query has the colors hardcoded, we always fetch all of them!
// And then we look up the specific colors
const [results, _] = await db.query( const [results, _] = await db.query(
` `
CALL GetItemsThatNeedModelsIfNotCached(?, @LastActualUpdate); CALL GetItemsThatNeedModelsIfNotCachedV2(?, @LastActualUpdate);
SELECT @LastActualUpdate; SELECT @LastActualUpdate;
`, `,
[lastKnownUpdate] [lastKnownUpdate]
@ -268,20 +271,18 @@ const buildItemsThatNeedModelsLoader = (db) =>
// Result 2 (required): The MySQL summary of the effects of the CALL. // Result 2 (required): The MySQL summary of the effects of the CALL.
// Result 3 (required): The 1-row table contianing @LastActualUpdate. // Result 3 (required): The 1-row table contianing @LastActualUpdate.
// //
// So, check the number of results. If it's 2, then there was no change, // So, check the number of results. If it's 3, then we should update our
// and we should return our cached value. Or, if it's 3, then we should // cache. Or, if it's 2, then there was no change and we can continue with
// update our cache. // the existing cached value.
if (results.length === 2) { if (results.length === 3) {
return [lastResult]; const [rawRows, __, varRows] = results;
} const rows = rawRows.map(normalizeRow);
const [rows, __, varRows] = results;
const entities = rows.map(normalizeRow);
lastKnownUpdate = varRows[0]["@LastActualUpdate"]; lastKnownUpdate = varRows[0]["@LastActualUpdate"];
lastResult = entities; lastResult = rows;
}
return [entities]; return [lastResult];
}); });
const buildPetTypeLoader = (db) => const buildPetTypeLoader = (db) =>

View file

@ -408,93 +408,12 @@ describe("Item", () => {
expect(getDbCalls()).toMatchInlineSnapshot(` expect(getDbCalls()).toMatchInlineSnapshot(`
Array [ Array [
Array [ Array [
" "SELECT * FROM item_translations WHERE item_id IN (?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?) AND locale = \\"en\\"",
SELECT items.id,
GROUP_CONCAT(DISTINCT pet_types.species_id ORDER BY pet_types.species_id)
AS modeled_species_ids,
-- Vandagyre was added on 2014-11-14, so we add some buffer here.
-- TODO: Some later Dyeworks items don't support Vandagyre.
-- Add a manual db flag?
items.created_at >= \\"2014-12-01\\" AS supports_vandagyre
FROM items
INNER JOIN parents_swf_assets psa
ON psa.parent_type = \\"Item\\" AND psa.parent_id = items.id
INNER JOIN swf_assets
ON swf_assets.id = psa.swf_asset_id
INNER JOIN pet_types
ON pet_types.body_id = swf_assets.body_id
WHERE
pet_types.color_id = \\"8\\"
GROUP BY items.id
HAVING
NOT (
-- Single species (probably just their item)
count(DISTINCT pet_types.species_id) = 1
-- All species modeled
OR modeled_species_ids = \\"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\\"
-- All species modeled except Vandagyre, for items that don't support it
OR (NOT supports_vandagyre AND modeled_species_ids = \\"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\\")
-- No species (either an All Bodies item, or a Capsule type thing)
OR modeled_species_ids = \\"\\"
)
ORDER BY items.id
",
],
Array [ Array [
"SELECT * FROM item_translations WHERE item_id IN (?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?) AND locale = \\"en\\"",
Array [
"24534",
"33850",
"34167",
"36125",
"36126",
"36245",
"36678",
"36729",
"36907", "36907",
"37354",
"37368",
"37840",
"38003",
"38130",
"38214",
"38216",
"38225",
"38311",
"38314",
"38391",
"39147",
"39148",
"39149",
"39313",
"39817",
"39884",
"41216",
"41690",
"41691",
"42169",
"42171",
"42448", "42448",
"42449",
"42475",
"42478",
"42544", "42544",
"42546", "42546",
"42823",
"42885",
"42886",
"42993",
"42994",
"43079",
"43081",
"43677",
"43694",
"44456",
"44507",
"45301",
"47054",
"47066",
"49408",
"50669", "50669",
"50670", "50670",
"50671", "50671",
@ -504,92 +423,30 @@ describe("Item", () => {
"51653", "51653",
"51654", "51654",
"51655", "51655",
"52684",
"53063",
"53324", "53324",
"53325", "53325",
"53762",
"53818",
"53820",
"54436",
"55596",
"55673",
"55675",
"56717",
"57295",
"58285", "58285",
"59848", "59848",
"60751",
"62302",
"62939", "62939",
"63077",
"63464",
"64195", "64195",
"64387", "64387",
"66493",
"67317", "67317",
"68228", "68228",
"68293",
"68470",
"69311", "69311",
"69743",
"69748",
"69754",
"69755",
"69756",
"69761",
"69772",
"69773",
"69782",
"69998",
"70843", "70843",
"71110", "71110",
"71658",
"71937", "71937",
"71938", "71938",
"72188",
"72553",
"72897",
"72898",
"72899",
"72906",
"72907",
"72908",
"72912",
"72913",
"72914",
"73094",
"73405",
"73598",
"73707", "73707",
"73708", "73708",
"73724", "73724",
"73766",
"74055",
"74259", "74259",
"74260", "74260",
"74261", "74261",
"74314",
"74315",
"75197",
"75198",
"75199",
"76108", "76108",
"76109", "76109",
"77441", "77441",
"77442", "77442",
"78318",
"78320",
"78560",
"78754",
"79847",
"80024",
"80427",
"80428",
"80774",
"81060",
"81061",
"81062",
"81144", "81144",
"81145", "81145",
"81229", "81229",
@ -605,72 +462,81 @@ describe("Item", () => {
"81243", "81243",
"81245", "81245",
"81246", "81246",
"81274",
"81371",
"81396",
"81547", "81547",
"81563", "81619",
"81630", "81630",
"81657",
"81658",
"81659",
"81660",
"81664",
"81667",
"81670",
"81671",
"81672",
"81674",
"81675",
"81693",
], ],
], ],
Array [ Array [
"SELECT * FROM species_translations "SELECT * FROM species_translations
WHERE species_id IN (?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?) AND locale = \\"en\\"", WHERE species_id IN (?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?,?) AND locale = \\"en\\"",
Array [ Array [
"18",
"24",
"25",
"48",
"49",
"20",
"6",
"27",
"41",
"42",
"5",
"47",
"50",
"51",
"4",
"11",
"12",
"14",
"23",
"37",
"21",
"1", "1",
"4",
"5",
"6",
"7", "7",
"8", "8",
"11",
"12",
"15", "15",
"16", "16",
"17", "17",
"19", "19",
"20",
"21",
"22", "22",
"23",
"24",
"26", "26",
"27",
"30", "30",
"32", "32",
"34", "34",
"36", "36",
"39", "39",
"40", "40",
"42",
"44", "44",
"47",
"48",
"49",
"50",
"54", "54",
"31", "2",
"33", "13",
"3", "14",
"9", "25",
"28",
"29", "29",
"35", "37",
"38", "38",
"43", "43",
"45", "45",
"46", "46",
"51",
"52", "52",
"53", "53",
"2", "3",
"9",
"31",
"41",
"10", "10",
"13", "18",
"28",
"35",
"33",
"55", "55",
], ],
], ],

File diff suppressed because it is too large Load diff

View file

@ -137,7 +137,9 @@ const resolvers = {
}, },
speciesThatNeedModels: async ({ id }, _, { itemsThatNeedModelsLoader }) => { speciesThatNeedModels: async ({ id }, _, { itemsThatNeedModelsLoader }) => {
const allItems = await itemsThatNeedModelsLoader.load("all"); const allItems = await itemsThatNeedModelsLoader.load("all");
const item = allItems.find((i) => i.id === id); const item = allItems.find(
(row) => row.itemId === id && row.colorId === "8"
);
const modeledSpeciesIds = item.modeledSpeciesIds.split(","); const modeledSpeciesIds = item.modeledSpeciesIds.split(",");
// HACK: Needs to be updated if more species are added! // HACK: Needs to be updated if more species are added!
const allSpeciesIds = Array.from( const allSpeciesIds = Array.from(
@ -207,8 +209,13 @@ const resolvers = {
return { query, zones, items }; return { query, zones, items };
}, },
itemsThatNeedModels: async (_, __, { itemsThatNeedModelsLoader }) => { itemsThatNeedModels: async (_, __, { itemsThatNeedModelsLoader }) => {
const items = await itemsThatNeedModelsLoader.load("all"); const rows = await itemsThatNeedModelsLoader.load("all");
return items.map(({ id }) => ({ id })); let itemIds = rows
.filter((row) => row.colorId === "8")
.map((row) => row.itemId);
itemIds = new Set(itemIds);
itemIds = [...itemIds].sort();
return itemIds.map((id) => ({ id }));
}, },
}, },
}; };