diff --git a/src/server/loaders.js b/src/server/loaders.js index 282d32b..4726635 100644 --- a/src/server/loaders.js +++ b/src/server/loaders.js @@ -538,53 +538,80 @@ async function runItemModelingQuery(db, filterToItemIds) { return await db.execute( ` SELECT T_ITEMS.item_id, - T_BODIES.color_id, - T_ITEMS.supports_vandagyre, - COUNT(*) AS modeled_species_count, - GROUP_CONCAT( - T_BODIES.species_id - ORDER BY T_BODIES.species_id - ) AS modeled_species_ids, - ( - SELECT GROUP_CONCAT(DISTINCT species_id ORDER BY species_id) - FROM pet_types WHERE color_id = T_BODIES.color_id - ) AS all_species_ids_for_this_color - FROM ( - -- NOTE: I found that extracting this as a separate query that runs - -- first made things WAAAY faster. Less to join/group, I guess? - SELECT DISTINCT items.id AS item_id, - swf_assets.body_id AS body_id, - -- 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 item_translations it ON it.item_id = items.id AND it.locale = "en" - WHERE items.modeling_status_hint IS NULL AND it.name NOT LIKE "%MME%" - AND ${itemIdsCondition} - ORDER BY item_id - ) T_ITEMS - INNER JOIN ( - SELECT DISTINCT body_id, species_id, color_id - FROM pet_types - WHERE color_id IN (6, 8, 44, 46) - ORDER BY body_id, species_id - ) T_BODIES ON T_ITEMS.body_id = T_BODIES.body_id - GROUP BY T_ITEMS.item_id, T_BODIES.color_id - HAVING NOT ( - -- No species (either an All Bodies item, or a Capsule type thing) - modeled_species_count = 0 - -- Single species (probably just their item) - OR modeled_species_count = 1 - -- All species modeled (that are compatible with this color) - OR modeled_species_ids = all_species_ids_for_this_color - -- All species modeled except Vandagyre, for items that don't support it - OR (NOT T_ITEMS.supports_vandagyre AND modeled_species_count = 54 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") - ) - ORDER BY T_ITEMS.item_id; + T_BODIES.color_id, + T_ITEMS.supports_vandagyre, + COUNT(*) AS modeled_species_count, + GROUP_CONCAT( + T_BODIES.species_id + ORDER BY T_BODIES.species_id + ) AS modeled_species_ids, + ( + SELECT GROUP_CONCAT(DISTINCT species_id ORDER BY species_id) + FROM pet_types T_PT1 + WHERE color_id = T_BODIES.color_id + AND ( + -- For non-standard colors, ignore the species that have the same + -- body ID as standard pets. Otherwise, a lot of items will be + -- like "oh, we fit the Maraquan Koi and Maraquan Mynci, where + -- are all the other Maraquans??", which is incorrect! + color_id = 8 + OR + ( + SELECT count(*) FROM pet_types T_PT2 + WHERE T_PT1.body_id = T_PT2.body_id + AND T_PT1.color_id != T_PT2.color_id + ) = 0 + ) + ) AS all_species_ids_for_this_color + FROM ( + -- NOTE: I found that extracting this as a separate query that runs + -- first made things WAAAY faster. Less to join/group, I guess? + SELECT DISTINCT items.id AS item_id, + swf_assets.body_id AS body_id, + -- 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 item_translations it ON it.item_id = items.id AND it.locale = "en" + WHERE items.modeling_status_hint IS NULL AND it.name NOT LIKE "%MME%" + AND ${itemIdsCondition} + ORDER BY item_id + ) T_ITEMS + INNER JOIN ( + SELECT DISTINCT body_id, species_id, color_id + FROM pet_types T_PT1 + WHERE color_id IN (6, 8, 44, 46) + AND ( + -- For non-standard colors, ignore the species that have the same + -- body ID as standard pets. Otherwise, a lot of items will be + -- like "oh, we fit the Maraquan Koi and Maraquan Mynci, where + -- are all the other Maraquans??", which is incorrect! + color_id = 8 + OR + ( + SELECT count(*) FROM pet_types T_PT2 + WHERE T_PT1.body_id = T_PT2.body_id + AND T_PT1.color_id != T_PT2.color_id + ) = 0 + ) + ORDER BY body_id, species_id + ) T_BODIES ON T_ITEMS.body_id = T_BODIES.body_id + GROUP BY T_ITEMS.item_id, T_BODIES.color_id + HAVING NOT ( + -- No species (either an All Bodies item, or a Capsule type thing) + modeled_species_count = 0 + -- Single species (probably just their item) + OR modeled_species_count = 1 + -- All species modeled (that are compatible with this color) + OR modeled_species_ids = all_species_ids_for_this_color + -- All species modeled except Vandagyre, for items that don't support it + OR (NOT T_ITEMS.supports_vandagyre AND modeled_species_count = 54 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") + ) + ORDER BY T_ITEMS.item_id; `, [...itemIdsValues] );