Query Optimization

This commit is contained in:
Geometrically
2021-01-24 21:33:32 -07:00
parent 5385431051
commit b5378c1296
5 changed files with 694 additions and 504 deletions

View File

@@ -401,108 +401,87 @@ impl Mod {
where
E: sqlx::Executor<'a, Database = sqlx::Postgres> + Copy,
{
let result = Self::get(id, executor).await?;
if let Some(inner) = result {
use futures::TryStreamExt;
let categories: Vec<String> = sqlx::query!(
"
SELECT category FROM mods_categories
INNER JOIN categories ON joining_category_id = id
WHERE joining_mod_id = $1
",
id as ModId,
)
.fetch_many(executor)
.try_filter_map(|e| async { Ok(e.right().map(|c| c.category)) })
.try_collect::<Vec<String>>()
.await?;
let versions: Vec<VersionId> = sqlx::query!(
"
SELECT id FROM versions
WHERE mod_id = $1
",
id as ModId,
)
.fetch_many(executor)
.try_filter_map(|e| async { Ok(e.right().map(|c| VersionId(c.id))) })
.try_collect::<Vec<VersionId>>()
.await?;
let donations: Vec<DonationUrl> = sqlx::query!(
"
SELECT d.joining_platform_id, d.url, dp.short, dp.name FROM mods_donations d
INNER JOIN donation_platforms dp ON d.joining_platform_id=dp.id
WHERE joining_mod_id = $1
",
id as ModId,
)
.fetch_many(executor)
.try_filter_map(|e| async {
Ok(e.right().map(|c| DonationUrl {
mod_id: id,
platform_id: DonationPlatformId(c.joining_platform_id),
platform_short: c.short,
platform_name: c.name,
url: c.url,
}))
})
.try_collect::<Vec<DonationUrl>>()
.await?;
let status = sqlx::query!(
"
SELECT status FROM statuses
WHERE id = $1
",
inner.status.0,
)
.fetch_one(executor)
.await?
.status;
let client_side = sqlx::query!(
"
SELECT name FROM side_types
WHERE id = $1
",
inner.client_side.0,
)
.fetch_one(executor)
.await?
.name;
let server_side = sqlx::query!(
"
SELECT name FROM side_types
WHERE id = $1
",
inner.server_side.0,
)
.fetch_one(executor)
.await?
.name;
let license = sqlx::query!(
"
SELECT short, name FROM licenses
WHERE id = $1
",
inner.license.0,
)
.fetch_one(executor)
let result = sqlx::query!(
"
SELECT m.id id, m.title title, m.description description, m.downloads downloads,
m.icon_url icon_url, m.body body, m.body_url body_url, m.published published,
m.updated updated, m.status status,
m.issues_url issues_url, m.source_url source_url, m.wiki_url wiki_url, m.discord_url discord_url, m.license_url license_url,
m.team_id team_id, m.client_side client_side, m.server_side server_side, m.license license, m.slug slug,
s.status status_name, cs.name client_side_type, ss.name server_side_type, l.short short, l.name license_name,
ARRAY_AGG( DISTINCT c.category) categories, ARRAY_AGG(DISTINCT v.id) versions, ARRAY_AGG(DISTINCT md.joining_platform_id || ', ' || md.url || ', ' || dp.short || ', ' || dp.name) donations
FROM mods m
INNER JOIN mods_categories mc ON joining_mod_id = m.id
INNER JOIN categories c ON mc.joining_category_id = c.id
INNER JOIN versions v ON v.mod_id = m.id
INNER JOIN mods_donations md ON md.joining_mod_id = m.id
INNER JOIN donation_platforms dp ON md.joining_platform_id = dp.id
INNER JOIN statuses s ON s.id = m.status
INNER JOIN side_types cs ON m.client_side = cs.id
INNER JOIN side_types ss ON m.server_side = ss.id
INNER JOIN licenses l ON m.license = l.id
WHERE m.id IN (SELECT * FROM UNNEST($1::bigint[]))
GROUP BY m.id, s.id, cs.id, ss.id, l.id;
",
id as ModId,
)
.fetch_optional(executor)
.await?;
if let Some(m) = result {
Ok(Some(QueryMod {
inner,
categories,
versions,
donation_urls: donations,
status: crate::models::mods::ModStatus::from_str(&status),
license_id: license.short,
license_name: license.name,
client_side: crate::models::mods::SideType::from_str(&client_side),
server_side: crate::models::mods::SideType::from_str(&server_side),
inner: Mod {
id: ModId(m.id.clone()),
team_id: TeamId(m.team_id.clone()),
title: m.title.clone(),
description: m.description.clone(),
downloads: m.downloads.clone(),
body_url: m.body_url.clone(),
icon_url: m.icon_url.clone(),
published: m.published.clone(),
updated: m.updated.clone(),
issues_url: m.issues_url.clone(),
source_url: m.source_url.clone(),
wiki_url: m.wiki_url.clone(),
license_url: m.license_url.clone(),
discord_url: m.discord_url.clone(),
client_side: SideTypeId(m.client_side.clone()),
status: StatusId(m.status.clone()),
server_side: SideTypeId(m.server_side.clone()),
license: LicenseId(m.license.clone()),
slug: m.slug.clone(),
body: m.body.clone(),
},
categories: m.categories.clone().unwrap_or(vec![]),
versions: m
.versions
.clone()
.unwrap_or(vec![])
.into_iter()
.map(|v| VersionId(v))
.collect(),
donation_urls: m
.donations
.clone()
.unwrap_or(vec![])
.into_iter()
.map(|d| {
// TODO: Change this once SQLX allows postgres tuples
let strings: Vec<&str> = d.split(", ").collect();
DonationUrl {
mod_id: ModId(m.id.clone()),
platform_id: DonationPlatformId(strings[0].parse().unwrap_or(0)),
platform_short: strings[2].to_string(),
platform_name: strings[3].to_string(),
url: strings[1].to_string(),
}
})
.collect(),
status: crate::models::mods::ModStatus::from_str(&m.status_name),
license_id: m.short,
license_name: m.license_name,
client_side: crate::models::mods::SideType::from_str(&m.client_side_type),
server_side: crate::models::mods::SideType::from_str(&m.server_side_type),
}))
} else {
Ok(None)
@@ -512,19 +491,84 @@ impl Mod {
pub async fn get_many_full<'a, E>(
mod_ids: Vec<ModId>,
exec: E,
) -> Result<Vec<Option<QueryMod>>, sqlx::Error>
) -> Result<Vec<QueryMod>, sqlx::Error>
where
E: sqlx::Executor<'a, Database = sqlx::Postgres> + Copy,
{
let mut mods = Vec::new();
use futures::TryStreamExt;
for mod_id in mod_ids {
mods.push(Self::get_full(mod_id, exec).await?)
}
Ok(mods)
/*// TODO: this could be optimized
futures::future::try_join_all(mod_ids.into_iter().map(|id| Self::get_full(id, exec))).await*/
let mod_ids_parsed: Vec<i64> = mod_ids.into_iter().map(|x| x.0).collect();
sqlx::query!(
"
SELECT m.id id, m.title title, m.description description, m.downloads downloads,
m.icon_url icon_url, m.body body, m.body_url body_url, m.published published,
m.updated updated, m.status status,
m.issues_url issues_url, m.source_url source_url, m.wiki_url wiki_url, m.discord_url discord_url, m.license_url license_url,
m.team_id team_id, m.client_side client_side, m.server_side server_side, m.license license, m.slug slug,
s.status status_name, cs.name client_side_type, ss.name server_side_type, l.short short, l.name license_name,
ARRAY_AGG( DISTINCT c.category) categories, ARRAY_AGG(DISTINCT v.id) versions, ARRAY_AGG(DISTINCT md.joining_platform_id || ', ' || md.url || ', ' || dp.short || ', ' || dp.name) donations
FROM mods m
INNER JOIN mods_categories mc ON joining_mod_id = m.id
INNER JOIN categories c ON mc.joining_category_id = c.id
INNER JOIN versions v ON v.mod_id = m.id
INNER JOIN mods_donations md ON md.joining_mod_id = m.id
INNER JOIN donation_platforms dp ON md.joining_platform_id = dp.id
INNER JOIN statuses s ON s.id = m.status
INNER JOIN side_types cs ON m.client_side = cs.id
INNER JOIN side_types ss ON m.server_side = ss.id
INNER JOIN licenses l ON m.license = l.id
WHERE m.id IN (SELECT * FROM UNNEST($1::bigint[]))
GROUP BY m.id, s.id, cs.id, ss.id, l.id;
",
&mod_ids_parsed
)
.fetch_many(exec)
.try_filter_map(|e| async {
Ok(e.right().map(|m| QueryMod {
inner: Mod {
id: ModId(m.id.clone()),
team_id: TeamId(m.team_id.clone()),
title: m.title.clone(),
description: m.description.clone(),
downloads: m.downloads.clone(),
body_url: m.body_url.clone(),
icon_url: m.icon_url.clone(),
published: m.published.clone(),
updated: m.updated.clone(),
issues_url: m.issues_url.clone(),
source_url: m.source_url.clone(),
wiki_url: m.wiki_url.clone(),
license_url: m.license_url.clone(),
discord_url: m.discord_url.clone(),
client_side: SideTypeId(m.client_side.clone()),
status: StatusId(m.status.clone()),
server_side: SideTypeId(m.server_side.clone()),
license: LicenseId(m.license.clone()),
slug: m.slug.clone(),
body: m.body.clone(),
},
categories: m.categories.clone().unwrap_or(vec![]),
versions: m.versions.clone().unwrap_or(vec![]).into_iter().map(|v| VersionId(v)).collect(),
donation_urls: m.donations.clone().unwrap_or(vec![]).into_iter().map(|d| {
// TODO: Change this once SQLX allows postgres tuples
let strings : Vec<&str> = d.split(", ").collect();
DonationUrl {
mod_id: ModId(m.id.clone()),
platform_id: DonationPlatformId(strings[0].parse().unwrap_or(0)),
platform_short: strings[2].to_string(),
platform_name: strings[3].to_string(),
url: strings[1].to_string()
}
}).collect(),
status: crate::models::mods::ModStatus::from_str(&m.status_name),
license_id: m.short,
license_name: m.license_name,
client_side: crate::models::mods::SideType::from_str(&m.client_side_type),
server_side: crate::models::mods::SideType::from_str(&m.server_side_type),
}))
})
.try_collect::<Vec<QueryMod>>()
.await
}
}