Skip to content

Commit

Permalink
feat: improve variant parsing, item traits and duplicates
Browse files Browse the repository at this point in the history
* expand dice logic to weapon damage data
* handle separate weapon/shield/armor creature association
* handle separate weapon/shield/armor trait association
* fix elite level -1
* get avg now is implemented in dice and can handle a weapon with multiple damage sources
*
  • Loading branch information
RakuJa committed Jul 18, 2024
1 parent 1d57ba2 commit 9835663
Show file tree
Hide file tree
Showing 13 changed files with 303 additions and 98 deletions.
23 changes: 11 additions & 12 deletions build/creature_core_db_init.rs
Original file line number Diff line number Diff line change
Expand Up @@ -47,19 +47,18 @@ async fn create_temporary_table(conn: &Pool<Sqlite>) -> Result<()> {
ct.source,
ct.remaster,
CASE WHEN ct.id IN (
SELECT creature_id FROM (
SELECT wcat.creature_id, base_item_id FROM ITEM_CREATURE_ASSOCIATION_TABLE wcat LEFT JOIN (
SELECT * FROM WEAPON_TABLE w1 WHERE UPPER(w1.weapon_type) = 'MELEE'
) wt ON base_item_id = wcat.item_id
)
SELECT wcat.creature_id
FROM WEAPON_CREATURE_ASSOCIATION_TABLE wcat LEFT JOIN (
SELECT * FROM WEAPON_TABLE w1 WHERE UPPER(w1.weapon_type) = 'MELEE'
) wt ON base_item_id = wcat.weapon_id
) THEN TRUE ELSE FALSE END AS is_melee,
CASE WHEN ct.id IN (
SELECT creature_id FROM (
SELECT wcat.creature_id, base_item_id FROM ITEM_CREATURE_ASSOCIATION_TABLE wcat LEFT JOIN (
SELECT * FROM WEAPON_TABLE w1 WHERE UPPER(w1.weapon_type) = 'RANGED'
) wt ON base_item_id = wcat.item_id
)
) THEN TRUE ELSE FALSE END AS is_ranged,
CASE WHEN ct.id IN (
SELECT wcat.creature_id
FROM WEAPON_CREATURE_ASSOCIATION_TABLE wcat LEFT JOIN (
SELECT * FROM WEAPON_TABLE w1 WHERE UPPER(w1.weapon_type) = 'MELEE'
) wt ON base_item_id = wcat.weapon_id
)
THEN TRUE ELSE FALSE END AS is_ranged,
CASE WHEN st.creature_id IS NOT NULL THEN TRUE ELSE FALSE END AS is_spell_caster,
CASE WHEN ct.aon_id IS NOT NULL THEN CONCAT('https://2e.aonprd.com/', CAST(UPPER(COALESCE(UPPER(ct.cr_type) , 'MONSTER')) AS TEXT), 's' , '.aspx?ID=', CAST(ct.aon_id AS TEXT)) ELSE NULL END AS archive_link,
COALESCE(ct.cr_type , 'Monster') AS cr_type,
Expand Down
105 changes: 81 additions & 24 deletions src/db/data_providers/creature_fetcher.rs
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
use crate::db::data_providers::generic_fetcher::{
fetch_armor_runes, fetch_item_traits, fetch_weapon_runes, MyString,
fetch_armor_runes, fetch_armor_traits, fetch_item_traits, fetch_shield_traits,
fetch_weapon_damage_data, fetch_weapon_runes, fetch_weapon_traits, MyString,
};
use crate::db::data_providers::raw_query_builder::prepare_filtered_get_creatures_core;
use crate::models::creature::creature_component::creature_combat::{
Expand Down Expand Up @@ -210,15 +211,14 @@ pub async fn fetch_creature_traits(conn: &Pool<Sqlite>, creature_id: i64) -> Res
async fn fetch_creature_weapons(conn: &Pool<Sqlite>, creature_id: i64) -> Result<Vec<Weapon>> {
let weapons: Vec<Weapon> = sqlx::query_as(
"
SELECT wt.id AS weapon_id, wt.bonus_dmg, wt.to_hit_bonus, wt.dmg_type,
wt.number_of_dice, wt.die_size, wt.splash_dmg, wt.n_of_potency_runes,
SELECT wt.id AS weapon_id, wt.to_hit_bonus, wt.splash_dmg, wt.n_of_potency_runes,
wt.n_of_striking_runes, wt.range, wt.reload, wt.weapon_type, wt.base_item_id,
it.*
FROM WEAPON_TABLE wt LEFT JOIN ITEM_TABLE it ON it.id = wt.base_item_id
WHERE base_item_id IN (
SELECT item_id FROM ITEM_CREATURE_ASSOCIATION_TABLE WHERE creature_id == ($1)
)
GROUP BY it.id
FROM WEAPON_CREATURE_ASSOCIATION_TABLE ica
LEFT JOIN WEAPON_TABLE wt ON wt.id = ica.weapon_id
LEFT JOIN ITEM_TABLE it ON it.id = wt.base_item_id
WHERE ica.creature_id = ($1)
GROUP BY ica.weapon_id
ORDER BY name
",
)
Expand All @@ -227,13 +227,16 @@ async fn fetch_creature_weapons(conn: &Pool<Sqlite>, creature_id: i64) -> Result
.await?;
let mut result_vec = Vec::new();
for mut el in weapons {
el.item_core.traits = fetch_item_traits(conn, el.item_core.id)
el.item_core.traits = fetch_weapon_traits(conn, el.weapon_data.id)
.await
.unwrap_or(vec![]);
el.item_core.quantity = fetch_item_quantity(conn, creature_id, el.item_core.id).await;
el.item_core.quantity = fetch_weapon_quantity(conn, creature_id, el.weapon_data.id).await;
el.weapon_data.property_runes = fetch_weapon_runes(conn, el.weapon_data.id)
.await
.unwrap_or(vec![]);
el.weapon_data.damage_data = fetch_weapon_damage_data(conn, el.weapon_data.id)
.await
.unwrap_or(vec![]);
result_vec.push(el)
}
Ok(result_vec)
Expand All @@ -245,11 +248,11 @@ async fn fetch_creature_armors(conn: &Pool<Sqlite>, creature_id: i64) -> Result<
SELECT at.id AS armor_id, at.bonus_ac, at.check_penalty, at.dex_cap, at.n_of_potency_runes,
at.n_of_resilient_runes, at.speed_penalty, at.strength_required, at.base_item_id,
it.*
FROM ARMOR_TABLE at LEFT JOIN ITEM_TABLE it ON it.id = at.base_item_id
WHERE base_item_id IN (
SELECT item_id FROM ITEM_CREATURE_ASSOCIATION_TABLE WHERE creature_id == ($1)
)
GROUP BY it.id
FROM ARMOR_CREATURE_ASSOCIATION_TABLE aca
LEFT JOIN ARMOR_TABLE at ON at.id = aca.armor_id
LEFT JOIN ITEM_TABLE it ON it.id = at.base_item_id
WHERE aca.creature_id = ($1)
GROUP BY aca.armor_id
ORDER BY name
",
)
Expand All @@ -258,10 +261,10 @@ async fn fetch_creature_armors(conn: &Pool<Sqlite>, creature_id: i64) -> Result<
.await?;
let mut result_vec = Vec::new();
for mut el in armors {
el.item_core.traits = fetch_item_traits(conn, el.item_core.id)
el.item_core.traits = fetch_armor_traits(conn, el.armor_data.id)
.await
.unwrap_or(vec![]);
el.item_core.quantity = fetch_item_quantity(conn, creature_id, el.item_core.id).await;
el.item_core.quantity = fetch_armor_quantity(conn, creature_id, el.armor_data.id).await;
el.armor_data.property_runes = fetch_armor_runes(conn, el.armor_data.id)
.await
.unwrap_or(vec![]);
Expand All @@ -275,11 +278,11 @@ async fn fetch_creature_shields(conn: &Pool<Sqlite>, creature_id: i64) -> Result
"
SELECT st.id AS shield_id, st.bonus_ac, st.n_of_reinforcing_runes, st.speed_penalty,
it.*
FROM SHIELD_TABLE st LEFT JOIN ITEM_TABLE it ON it.id = st.base_item_id
WHERE base_item_id IN (
SELECT item_id FROM ITEM_CREATURE_ASSOCIATION_TABLE WHERE creature_id == ($1)
)
GROUP BY it.id
FROM SHIELD_CREATURE_ASSOCIATION_TABLE sca
LEFT JOIN SHIELD_TABLE st ON st.id = sca.shield_id
LEFT JOIN ITEM_TABLE it ON it.id = st.base_item_id
WHERE sca.creature_id = ($1)
GROUP BY sca.shield_id
ORDER BY name
",
)
Expand All @@ -288,10 +291,10 @@ async fn fetch_creature_shields(conn: &Pool<Sqlite>, creature_id: i64) -> Result
.await?;
let mut result_vec = Vec::new();
for mut el in shields {
el.item_core.traits = fetch_item_traits(conn, el.item_core.id)
el.item_core.traits = fetch_shield_traits(conn, el.shield_data.id)
.await
.unwrap_or(vec![]);
el.item_core.quantity = fetch_item_quantity(conn, creature_id, el.item_core.id).await;
el.item_core.quantity = fetch_shield_quantity(conn, creature_id, el.shield_data.id).await;
result_vec.push(el)
}
Ok(result_vec)
Expand Down Expand Up @@ -336,6 +339,60 @@ async fn fetch_item_quantity(conn: &Pool<Sqlite>, creature_id: i64, item_id: i64
}
}

/// Quantities are present ONLY for creature's weapons.
/// It needs to be fetched from the association table.
/// It defaults to 1 if error are found
async fn fetch_weapon_quantity(conn: &Pool<Sqlite>, creature_id: i64, weapon_id: i64) -> i64 {
match sqlx::query!(
"SELECT quantity FROM WEAPON_CREATURE_ASSOCIATION_TABLE WHERE
creature_id == ($1) AND weapon_id == ($2)",
creature_id,
weapon_id
)
.fetch_one(conn)
.await
{
Ok(r) => r.quantity,
Err(_) => 1,
}
}

/// Quantities are present ONLY for creature's shields.
/// It needs to be fetched from the association table.
/// It defaults to 1 if error are found
async fn fetch_shield_quantity(conn: &Pool<Sqlite>, creature_id: i64, shield_id: i64) -> i64 {
match sqlx::query!(
"SELECT quantity FROM SHIELD_CREATURE_ASSOCIATION_TABLE WHERE
creature_id == ($1) AND shield_id == ($2)",
creature_id,
shield_id
)
.fetch_one(conn)
.await
{
Ok(r) => r.quantity,
Err(_) => 1,
}
}

/// Quantities are present ONLY for creature's armors.
/// It needs to be fetched from the association table.
/// It defaults to 1 if error are found
async fn fetch_armor_quantity(conn: &Pool<Sqlite>, creature_id: i64, armor_id: i64) -> i64 {
match sqlx::query!(
"SELECT quantity FROM ARMOR_CREATURE_ASSOCIATION_TABLE WHERE
creature_id == ($1) AND armor_id == ($2)",
creature_id,
armor_id
)
.fetch_one(conn)
.await
{
Ok(r) => r.quantity,
Err(_) => 1,
}
}

async fn fetch_creature_actions(conn: &Pool<Sqlite>, creature_id: i64) -> Result<Vec<Action>> {
Ok(sqlx::query_as!(
Action,
Expand Down
58 changes: 58 additions & 0 deletions src/db/data_providers/generic_fetcher.rs
Original file line number Diff line number Diff line change
@@ -1,3 +1,4 @@
use crate::models::item::weapon_struct::DamageData;
use anyhow::Result;
use sqlx::{FromRow, Pool, Sqlite};

Expand Down Expand Up @@ -33,6 +34,51 @@ pub async fn fetch_item_traits(conn: &Pool<Sqlite>, item_id: i64) -> Result<Vec<
.collect())
}

pub async fn fetch_weapon_traits(conn: &Pool<Sqlite>, weapon_id: i64) -> Result<Vec<String>> {
Ok(sqlx::query_as!(
MyString,
"SELECT name AS my_str
FROM TRAIT_TABLE INTERSECT
SELECT trait_id FROM TRAIT_WEAPON_ASSOCIATION_TABLE WHERE weapon_id == ($1)",
weapon_id
)
.fetch_all(conn)
.await?
.into_iter()
.map(|x| x.my_str)
.collect())
}

pub async fn fetch_shield_traits(conn: &Pool<Sqlite>, shield_id: i64) -> Result<Vec<String>> {
Ok(sqlx::query_as!(
MyString,
"SELECT name AS my_str
FROM TRAIT_TABLE INTERSECT
SELECT trait_id FROM TRAIT_SHIELD_ASSOCIATION_TABLE WHERE shield_id == ($1)",
shield_id
)
.fetch_all(conn)
.await?
.into_iter()
.map(|x| x.my_str)
.collect())
}

pub async fn fetch_armor_traits(conn: &Pool<Sqlite>, armor_id: i64) -> Result<Vec<String>> {
Ok(sqlx::query_as!(
MyString,
"SELECT name AS my_str
FROM TRAIT_TABLE INTERSECT
SELECT trait_id FROM TRAIT_ARMOR_ASSOCIATION_TABLE WHERE armor_id == ($1)",
armor_id
)
.fetch_all(conn)
.await?
.into_iter()
.map(|x| x.my_str)
.collect())
}

pub async fn fetch_weapon_runes(conn: &Pool<Sqlite>, wp_id: i64) -> Result<Vec<String>> {
Ok(sqlx::query_as!(
MyString,
Expand All @@ -48,6 +94,18 @@ pub async fn fetch_weapon_runes(conn: &Pool<Sqlite>, wp_id: i64) -> Result<Vec<S
.collect())
}

pub async fn fetch_weapon_damage_data(conn: &Pool<Sqlite>, wp_id: i64) -> Result<Vec<DamageData>> {
Ok(sqlx::query_as(
"SELECT id, bonus_dmg, dmg_type, number_of_dice, die_size
FROM WEAPON_DAMAGE_TABLE dm RIGHT JOIN (
SELECT id AS wp_id FROM WEAPON_TABLE WHERE wp_id == ($1)
) ON wp_id == dm.weapon_id",
)
.bind(wp_id)
.fetch_all(conn)
.await?)
}

pub async fn fetch_armor_runes(conn: &Pool<Sqlite>, wp_id: i64) -> Result<Vec<String>> {
Ok(sqlx::query_as!(
MyString,
Expand Down
24 changes: 20 additions & 4 deletions src/db/data_providers/raw_query_builder.rs
Original file line number Diff line number Diff line change
Expand Up @@ -211,10 +211,26 @@ fn prepare_item_subquery(
}

fn prepare_get_id_matching_item_type_query(item_type: &ItemTypeEnum) -> String {
let (item_id_field, type_query) = match item_type {
ItemTypeEnum::Consumable | ItemTypeEnum::Equipment => {
("id", "AND UPPER(item_type) = UPPER('{item_type}')")
}
// There is no need for an and statement here, we already fetch from the "private" table.
// Item instead contains a lot of item_type (it's the base for weapon/shield/etc)
ItemTypeEnum::Weapon | ItemTypeEnum::Armor | ItemTypeEnum::Shield => ("base_item_id", ""),
};
let tass_item_id_field = match item_type {
ItemTypeEnum::Consumable | ItemTypeEnum::Equipment => "item_id",
ItemTypeEnum::Weapon => "weapon_id",
ItemTypeEnum::Armor => "armor_id",
ItemTypeEnum::Shield => "shield_id",
};
format!(
"SELECT id FROM ITEM_TABLE it
LEFT OUTER JOIN ITEM_CREATURE_ASSOCIATION_TABLE icat ON it.id = icat.item_id
WHERE icat.item_id IS NULL
AND UPPER(item_type) = UPPER('{item_type}')"
"
SELECT {item_id_field} FROM {} tmain
LEFT OUTER JOIN {} tass ON tmain.id = tass.{tass_item_id_field}
WHERE tass.{tass_item_id_field} IS NULL {type_query}",
item_type.to_db_main_table_name(),
item_type.to_db_association_table_name(),
)
}
32 changes: 16 additions & 16 deletions src/db/data_providers/shop_fetcher.rs
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
use crate::db::data_providers::generic_fetcher::{
fetch_armor_runes, fetch_item_traits, fetch_weapon_runes, MyString,
fetch_armor_runes, fetch_item_traits, fetch_weapon_damage_data, fetch_weapon_runes, MyString,
};
use crate::db::data_providers::raw_query_builder::prepare_filtered_get_items;
use crate::models::item::armor_struct::{Armor, ArmorData};
Expand Down Expand Up @@ -61,6 +61,7 @@ async fn fetch_weapon_by_item_id(conn: &Pool<Sqlite>, item_id: i64) -> Result<We
.await?;
weapon.item_core.traits = fetch_item_traits(conn, item_id).await?;
weapon.weapon_data.property_runes = fetch_weapon_runes(conn, weapon.weapon_data.id).await?;
weapon.weapon_data.damage_data = fetch_weapon_damage_data(conn, weapon.weapon_data.id).await?;
Ok(weapon)
}

Expand Down Expand Up @@ -136,14 +137,14 @@ pub async fn fetch_weapons(
) -> Result<Vec<Weapon>> {
let x: Vec<Weapon> = sqlx::query_as(
"
SELECT wt.id AS weapon_id, wt.bonus_dmg, wt.to_hit_bonus, wt.dmg_type, wt.number_of_dice, wt.die_size, wt.splash_dmg,
wt.n_of_potency_runes, wt.n_of_striking_runes, wt.range, wt.reload, wt.weapon_type, wt.base_item_id,
SELECT wt.id AS weapon_id, wt.to_hit_bonus, wt.splash_dmg, wt.n_of_potency_runes,
wt.n_of_striking_runes, wt.range, wt.reload, wt.weapon_type, wt.base_item_id,
it.*
FROM WEAPON_TABLE wt
LEFT OUTER JOIN ITEM_CREATURE_ASSOCIATION_TABLE icat
ON wt.base_item_id = icat.item_id
LEFT OUTER JOIN WEAPON_CREATURE_ASSOCIATION_TABLE wcat
ON wt.id = wcat.weapon_id
LEFT JOIN ITEM_TABLE it ON wt.base_item_id = it.id
WHERE icat.item_id IS NULL
WHERE wcat.weapon_id IS NULL
GROUP BY it.id
ORDER BY name LIMIT ?,?
",
Expand All @@ -156,6 +157,7 @@ pub async fn fetch_weapons(
for mut el in x {
el.item_core.traits = fetch_item_traits(conn, el.item_core.id).await?;
el.weapon_data.property_runes = fetch_weapon_runes(conn, el.weapon_data.id).await?;
el.weapon_data.damage_data = fetch_weapon_damage_data(conn, el.weapon_data.id).await?;
result_vec.push(Weapon {
item_core: el.item_core,
weapon_data: el.weapon_data,
Expand All @@ -168,13 +170,12 @@ pub async fn fetch_armors(conn: &Pool<Sqlite>, cursor: u32, page_size: i16) -> R
let x: Vec<Armor> = sqlx::query_as(
"
SELECT at.id AS armor_id, at.bonus_ac, at.check_penalty, at.dex_cap, at.n_of_potency_runes,
at.n_of_resilient_runes, at.speed_penalty, at.strength_required, at.base_item_id,
it.*
at.n_of_resilient_runes, at.speed_penalty, at.strength_required, at.base_item_id, it.*
FROM ARMOR_TABLE at
LEFT OUTER JOIN ITEM_CREATURE_ASSOCIATION_TABLE icat
ON at.base_item_id = icat.item_id
LEFT OUTER JOIN ARMOR_CREATURE_ASSOCIATION_TABLE acat
ON at.id = acat.armor_id
LEFT JOIN ITEM_TABLE it ON at.base_item_id = it.id
WHERE icat.item_id IS NULL
WHERE acat.armor_id IS NULL
GROUP BY it.id
ORDER BY name LIMIT ?,?
",
Expand Down Expand Up @@ -202,13 +203,12 @@ pub async fn fetch_shields(
) -> Result<Vec<Shield>> {
let x: Vec<Shield> = sqlx::query_as(
"
SELECT st.id AS shield_id, st.bonus_ac, st.n_of_reinforcing_runes, st.speed_penalty,
it.*
SELECT st.id AS shield_id, st.bonus_ac, st.n_of_reinforcing_runes, st.speed_penalty, it.*
FROM SHIELD_TABLE st
LEFT OUTER JOIN ITEM_CREATURE_ASSOCIATION_TABLE icat
ON st.base_item_id = icat.item_id
LEFT OUTER JOIN SHIELD_CREATURE_ASSOCIATION_TABLE scat
ON st.id = scat.shield_id
LEFT JOIN ITEM_TABLE it ON st.base_item_id = it.id
WHERE icat.item_id IS NULL
WHERE scat.shield_id IS NULL
GROUP BY it.id
ORDER BY name LIMIT ?,?
",
Expand Down
Loading

0 comments on commit 9835663

Please sign in to comment.