Query optimization (#235)

* Optimize version queries and decrease some query complexity

* Run formatter
This commit is contained in:
Geometrically 2021-08-20 16:33:09 -07:00 committed by GitHub
parent 07226c6d21
commit ffd9a34cf5
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
15 changed files with 1068 additions and 1138 deletions

View File

@ -0,0 +1,7 @@
ALTER TABLE versions ADD COLUMN version_type varchar(255) default 'release' NOT NULL;
UPDATE versions SET version_type = (SELECT rc.channel FROM release_channels rc WHERE rc.id = release_channel);
ALTER TABLE versions DROP COLUMN release_channel, ALTER COLUMN version_type DROP DEFAULT;
DROP TABLE release_channels;

File diff suppressed because it is too large Load Diff

View File

@ -1142,7 +1142,7 @@ impl ProjectType {
let project_types = sqlx::query!(
"
SELECT id, name FROM project_types
WHERE name IN (SELECT * FROM UNNEST($1::varchar[]))
WHERE name = ANY($1)
",
names
)

View File

@ -138,9 +138,6 @@ pub struct DonationPlatformId(pub i32);
pub struct VersionId(pub i64);
#[derive(Copy, Clone, Debug, Type)]
#[sqlx(transparent)]
pub struct ChannelId(pub i32);
#[derive(Copy, Clone, Debug, Type)]
#[sqlx(transparent)]
pub struct GameVersionId(pub i32);
#[derive(Copy, Clone, Debug, Type)]
#[sqlx(transparent)]

View File

@ -38,28 +38,6 @@ pub enum DatabaseError {
Other(String),
}
impl ids::ChannelId {
pub async fn get_id<'a, E>(
channel: &str,
exec: E,
) -> Result<Option<ids::ChannelId>, DatabaseError>
where
E: sqlx::Executor<'a, Database = sqlx::Postgres>,
{
let result = sqlx::query!(
"
SELECT id FROM release_channels
WHERE channel = $1
",
channel
)
.fetch_optional(exec)
.await?;
Ok(result.map(|r| ids::ChannelId(r.id)))
}
}
impl ids::StatusId {
pub async fn get_id<'a, E>(
status: &crate::models::projects::ProjectStatus,

View File

@ -183,7 +183,7 @@ impl Notification {
STRING_AGG(DISTINCT na.id || ', ' || na.title || ', ' || na.action_route || ', ' || na.action_route_method, ' ,') actions
FROM notifications n
LEFT OUTER JOIN notifications_actions na on n.id = na.notification_id
WHERE n.id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE n.id = ANY($1)
GROUP BY n.id, n.user_id
ORDER BY n.created DESC;
",
@ -319,7 +319,7 @@ impl Notification {
sqlx::query!(
"
DELETE FROM notifications_actions
WHERE notification_id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE notification_id = ANY($1)
",
&notification_ids_parsed
)
@ -329,7 +329,7 @@ impl Notification {
sqlx::query!(
"
DELETE FROM notifications
WHERE id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE id = ANY($1)
",
&notification_ids_parsed
)

View File

@ -310,7 +310,7 @@ impl Project {
team_id, client_side, server_side, license, slug,
moderation_message, moderation_message_body
FROM mods
WHERE id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE id = ANY($1)
",
&project_ids_parsed
)
@ -760,7 +760,7 @@ impl Project {
LEFT JOIN categories c ON mc.joining_category_id = c.id
LEFT JOIN versions v ON v.mod_id = m.id
LEFT JOIN mods_gallery mg ON mg.mod_id = m.id
WHERE m.id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE m.id = ANY($1)
GROUP BY pt.id, s.id, cs.id, ss.id, l.id, m.id;
",
&project_ids_parsed

View File

@ -85,7 +85,7 @@ impl Report {
}
pub async fn get_many<'a, E>(
version_ids: Vec<ReportId>,
report_ids: Vec<ReportId>,
exec: E,
) -> Result<Vec<QueryReport>, sqlx::Error>
where
@ -93,15 +93,15 @@ impl Report {
{
use futures::stream::TryStreamExt;
let version_ids_parsed: Vec<i64> = version_ids.into_iter().map(|x| x.0).collect();
let versions = sqlx::query!(
let report_ids_parsed: Vec<i64> = report_ids.into_iter().map(|x| x.0).collect();
let reports = sqlx::query!(
"
SELECT r.id, rt.name, r.mod_id, r.version_id, r.user_id, r.body, r.reporter, r.created
FROM reports r
INNER JOIN report_types rt ON rt.id = r.report_type_id
WHERE r.id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE r.id = ANY($1)
",
&version_ids_parsed
&report_ids_parsed
)
.fetch_many(exec)
.try_filter_map(|e| async {
@ -119,7 +119,7 @@ impl Report {
.try_collect::<Vec<QueryReport>>()
.await?;
Ok(versions)
Ok(reports)
}
pub async fn remove_full<'a, E>(id: ReportId, exec: E) -> Result<Option<()>, sqlx::Error>

View File

@ -162,7 +162,7 @@ impl User {
SELECT u.id, u.github_id, u.name, u.email,
u.avatar_url, u.username, u.bio,
u.created, u.role FROM users u
WHERE u.id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE u.id = ANY($1)
",
&user_ids_parsed
)
@ -315,7 +315,7 @@ impl User {
sqlx::query!(
"
DELETE FROM notifications_actions
WHERE notification_id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE notification_id = ANY($1)
",
&notifications
)
@ -394,7 +394,7 @@ impl User {
sqlx::query!(
"
DELETE FROM notifications_actions
WHERE notification_id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE notification_id = ANY($1)
",
&notifications
)

View File

@ -13,7 +13,7 @@ pub struct VersionBuilder {
pub dependencies: Vec<DependencyBuilder>,
pub game_versions: Vec<GameVersionId>,
pub loaders: Vec<LoaderId>,
pub release_channel: ChannelId,
pub version_type: String,
pub featured: bool,
}
@ -132,8 +132,8 @@ impl VersionBuilder {
changelog_url: None,
date_published: chrono::Utc::now(),
downloads: 0,
release_channel: self.release_channel,
featured: self.featured,
version_type: self.version_type,
};
version.insert(&mut *transaction).await?;
@ -192,8 +192,8 @@ impl VersionBuilder {
SELECT d.id id
FROM versions v
INNER JOIN dependencies d ON d.dependent_id = v.id
INNER JOIN game_versions_versions gvv ON gvv.joining_version_id = v.id AND gvv.game_version_id IN (SELECT * FROM UNNEST($2::integer[]))
INNER JOIN loaders_versions lv ON lv.version_id = v.id AND lv.loader_id IN (SELECT * FROM UNNEST($3::integer[]))
INNER JOIN game_versions_versions gvv ON gvv.joining_version_id = v.id AND gvv.game_version_id = ANY($2)
INNER JOIN loaders_versions lv ON lv.version_id = v.id AND lv.loader_id = ANY($3)
WHERE v.mod_id = $1
",
self.project_id as ProjectId,
@ -211,9 +211,9 @@ impl VersionBuilder {
"
UPDATE dependencies
SET dependency_id = $2
WHERE id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE id = ANY($1::bigint[])
",
&dependencies,
dependencies.as_slice(),
self.version_id as VersionId,
)
.execute(&mut *transaction)
@ -233,7 +233,7 @@ pub struct Version {
pub changelog_url: Option<String>,
pub date_published: chrono::DateTime<chrono::Utc>,
pub downloads: i32,
pub release_channel: ChannelId,
pub version_type: String,
pub featured: bool,
}
@ -247,7 +247,7 @@ impl Version {
INSERT INTO versions (
id, mod_id, author_id, name, version_number,
changelog, changelog_url, date_published,
downloads, release_channel, featured
downloads, version_type, featured
)
VALUES (
$1, $2, $3, $4, $5,
@ -265,7 +265,7 @@ impl Version {
self.changelog_url.as_ref(),
self.date_published,
self.downloads,
self.release_channel as ChannelId,
&self.version_type,
self.featured
)
.execute(&mut *transaction)
@ -274,7 +274,6 @@ impl Version {
Ok(())
}
// TODO: someone verify this
pub async fn remove_full(
id: VersionId,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
@ -428,8 +427,8 @@ impl Version {
"
SELECT v.id id
FROM versions v
INNER JOIN game_versions_versions gvv ON gvv.joining_version_id = v.id AND gvv.game_version_id IN (SELECT * FROM UNNEST($2::integer[]))
INNER JOIN loaders_versions lv ON lv.version_id = v.id AND lv.loader_id IN (SELECT * FROM UNNEST($3::integer[]))
INNER JOIN game_versions_versions gvv ON gvv.joining_version_id = v.id AND gvv.game_version_id = ANY($2)
INNER JOIN loaders_versions lv ON lv.version_id = v.id AND lv.loader_id = ANY($3)
WHERE v.mod_id = $1
ORDER BY v.date_published DESC
LIMIT 1
@ -521,7 +520,7 @@ impl Version {
"
SELECT v.mod_id, v.author_id, v.name, v.version_number,
v.changelog, v.changelog_url, v.date_published, v.downloads,
v.release_channel, v.featured
v.version_type, v.featured
FROM versions v
WHERE v.id = $1
",
@ -541,7 +540,7 @@ impl Version {
changelog_url: row.changelog_url,
date_published: row.date_published,
downloads: row.downloads,
release_channel: ChannelId(row.release_channel),
version_type: row.version_type,
featured: row.featured,
}))
} else {
@ -563,9 +562,9 @@ impl Version {
"
SELECT v.id, v.mod_id, v.author_id, v.name, v.version_number,
v.changelog, v.changelog_url, v.date_published, v.downloads,
v.release_channel, v.featured
v.version_type, v.featured
FROM versions v
WHERE v.id IN (SELECT * FROM UNNEST($1::bigint[]))
WHERE v.id = ANY($1)
ORDER BY v.date_published ASC
",
&version_ids_parsed
@ -582,8 +581,8 @@ impl Version {
changelog_url: v.changelog_url,
date_published: v.date_published,
downloads: v.downloads,
release_channel: ChannelId(v.release_channel),
featured: v.featured,
version_type: v.version_type,
}))
})
.try_collect::<Vec<Version>>()
@ -603,13 +602,12 @@ impl Version {
"
SELECT v.id id, v.mod_id mod_id, v.author_id author_id, v.name version_name, v.version_number version_number,
v.changelog changelog, v.changelog_url changelog_url, v.date_published date_published, v.downloads downloads,
rc.channel release_channel, v.featured featured,
v.version_type version_type, v.featured featured,
STRING_AGG(DISTINCT gv.version, ',') game_versions, STRING_AGG(DISTINCT l.loader, ',') loaders,
STRING_AGG(DISTINCT f.id || ', ' || f.filename || ', ' || f.is_primary || ', ' || f.url, ' ,') files,
STRING_AGG(DISTINCT h.algorithm || ', ' || encode(h.hash, 'escape') || ', ' || h.file_id, ' ,') hashes,
STRING_AGG(DISTINCT COALESCE(d.dependency_id, 0) || ', ' || COALESCE(d.mod_dependency_id, 0) || ', ' || d.dependency_type, ' ,') dependencies
FROM versions v
INNER JOIN release_channels rc on v.release_channel = rc.id
LEFT OUTER JOIN game_versions_versions gvv on v.id = gvv.joining_version_id
LEFT OUTER JOIN game_versions gv on gvv.game_version_id = gv.id
LEFT OUTER JOIN loaders_versions lv on v.id = lv.version_id
@ -618,7 +616,7 @@ impl Version {
LEFT OUTER JOIN hashes h on f.id = h.file_id
LEFT OUTER JOIN dependencies d on v.id = d.dependent_id
WHERE v.id = $1
GROUP BY rc.id, v.id;
GROUP BY v.id;
",
id as VersionId,
)
@ -656,7 +654,6 @@ impl Version {
changelog_url: v.changelog_url,
date_published: v.date_published,
downloads: v.downloads,
release_channel: v.release_channel,
files: v
.files
.unwrap_or_default()
@ -731,6 +728,7 @@ impl Version {
})
.flatten()
.collect(),
version_type: v.version_type,
}))
} else {
Ok(None)
@ -751,13 +749,12 @@ impl Version {
"
SELECT v.id id, v.mod_id mod_id, v.author_id author_id, v.name version_name, v.version_number version_number,
v.changelog changelog, v.changelog_url changelog_url, v.date_published date_published, v.downloads downloads,
rc.channel release_channel, v.featured featured,
v.version_type version_type, v.featured featured,
STRING_AGG(DISTINCT gv.version, ',') game_versions, STRING_AGG(DISTINCT l.loader, ',') loaders,
STRING_AGG(DISTINCT f.id || ', ' || f.filename || ', ' || f.is_primary || ', ' || f.url, ' ,') files,
STRING_AGG(DISTINCT h.algorithm || ', ' || encode(h.hash, 'escape') || ', ' || h.file_id, ' ,') hashes,
STRING_AGG(DISTINCT COALESCE(d.dependency_id, 0) || ', ' || COALESCE(d.mod_dependency_id, 0) || ', ' || d.dependency_type, ' ,') dependencies
FROM versions v
INNER JOIN release_channels rc on v.release_channel = rc.id
LEFT OUTER JOIN game_versions_versions gvv on v.id = gvv.joining_version_id
LEFT OUTER JOIN game_versions gv on gvv.game_version_id = gv.id
LEFT OUTER JOIN loaders_versions lv on v.id = lv.version_id
@ -765,8 +762,8 @@ impl Version {
LEFT OUTER JOIN files f on v.id = f.version_id
LEFT OUTER JOIN hashes h on f.id = h.file_id
LEFT OUTER JOIN dependencies d on v.id = d.dependent_id
WHERE v.id IN (SELECT * FROM UNNEST($1::bigint[]))
GROUP BY rc.id, v.id
WHERE v.id = ANY($1)
GROUP BY v.id
ORDER BY v.date_published ASC;
",
&version_ids_parsed
@ -798,7 +795,6 @@ impl Version {
changelog_url: v.changelog_url,
date_published: v.date_published,
downloads: v.downloads,
release_channel: v.release_channel,
files: v.files.unwrap_or_default().split(" ,").map(|f| {
let file: Vec<&str> = f.split(", ").collect();
@ -854,6 +850,7 @@ impl Version {
None
}
}).flatten().collect(),
version_type: v.version_type
}
}))
})
@ -862,11 +859,6 @@ impl Version {
}
}
pub struct ReleaseChannel {
pub id: ChannelId,
pub channel: String,
}
pub struct VersionFile {
pub id: FileId,
pub version_id: VersionId,
@ -893,7 +885,7 @@ pub struct QueryVersion {
pub date_published: chrono::DateTime<chrono::Utc>,
pub downloads: i32,
pub release_channel: String,
pub version_type: String,
pub files: Vec<QueryFile>,
pub game_versions: Vec<String>,
pub loaders: Vec<String>,

View File

@ -95,9 +95,8 @@ pub async fn maven_metadata(
}
let version_names = sqlx::query!(
"
SELECT version_number, release_channels.channel channel
SELECT version_number, version_type
FROM versions
LEFT JOIN release_channels ON release_channels.id = versions.release_channel
WHERE mod_id = $1
",
data.inner.id as database::models::ids::ProjectId
@ -117,7 +116,7 @@ pub async fn maven_metadata(
.to_string(),
release: version_names
.iter()
.rfind(|x| x.channel == "release")
.rfind(|x| x.version_type == "release")
.map_or("", |x| &x.version_number)
.to_string(),
versions: Versions {

View File

@ -729,11 +729,6 @@ async fn create_initial_version(
// Randomly generate a new id to be used for the version
let version_id: VersionId = models::generate_version_id(transaction).await?.into();
let release_channel =
models::ChannelId::get_id(version_data.release_channel.as_str(), &mut *transaction)
.await?
.expect("Release Channel not found in database");
let game_versions = version_data
.game_versions
.iter()
@ -786,8 +781,8 @@ async fn create_initial_version(
dependencies,
game_versions,
loaders,
release_channel,
featured: version_data.featured,
version_type: version_data.release_channel.to_string(),
};
Ok(version)

View File

@ -186,13 +186,6 @@ async fn version_create_inner(
let version_id: VersionId = models::generate_version_id(transaction).await?.into();
let release_channel = models::ChannelId::get_id(
version_create_data.release_channel.as_str(),
&mut *transaction,
)
.await?
.expect("Release channel not found in database");
let project_type = sqlx::query!(
"
SELECT name FROM project_types pt
@ -255,7 +248,7 @@ async fn version_create_inner(
dependencies,
game_versions,
loaders,
release_channel,
version_type: version_create_data.release_channel.to_string(),
featured: version_create_data.featured,
});

View File

@ -377,7 +377,7 @@ pub async fn get_versions_from_hashes(
"
SELECT h.hash hash, h.algorithm algorithm, f.version_id version_id FROM hashes h
INNER JOIN files f ON h.file_id = f.id
WHERE h.algorithm = $2 AND h.hash IN (SELECT * FROM UNNEST($1::bytea[]))
WHERE h.algorithm = $2 AND h.hash = ANY($1::bytea[])
",
hashes_parsed.as_slice(),
file_data.algorithm
@ -425,7 +425,7 @@ pub async fn download_files(
SELECT f.url url, h.hash hash, h.algorithm algorithm, f.version_id version_id, v.mod_id project_id FROM hashes h
INNER JOIN files f ON h.file_id = f.id
INNER JOIN versions v ON v.id = f.version_id
WHERE h.algorithm = $2 AND h.hash IN (SELECT * FROM UNNEST($1::bytea[]))
WHERE h.algorithm = $2 AND h.hash = ANY($1::bytea[])
",
hashes_parsed.as_slice(),
file_data.algorithm
@ -476,7 +476,7 @@ pub async fn update_files(
SELECT f.url url, h.hash hash, h.algorithm algorithm, f.version_id version_id, v.mod_id project_id FROM hashes h
INNER JOIN files f ON h.file_id = f.id
INNER JOIN versions v ON v.id = f.version_id
WHERE h.algorithm = $2 AND h.hash IN (SELECT * FROM UNNEST($1::bytea[]))
WHERE h.algorithm = $2 AND h.hash = ANY($1::bytea[])
",
hashes_parsed.as_slice(),
update_data.algorithm

View File

@ -160,7 +160,7 @@ pub fn convert_version(
changelog_url: data.changelog_url,
date_published: data.date_published,
downloads: data.downloads as u32,
version_type: match data.release_channel.as_str() {
version_type: match data.version_type.as_str() {
"release" => VersionType::Release,
"beta" => VersionType::Beta,
"alpha" => VersionType::Alpha,
@ -301,24 +301,13 @@ pub async fn version_edit(
}
if let Some(version_type) = &new_version.version_type {
let channel = database::models::ids::ChannelId::get_id(
version_type.as_str(),
&mut *transaction,
)
.await?
.ok_or_else(|| {
ApiError::InvalidInputError(
"No database entry for version type provided.".to_string(),
)
})?;
sqlx::query!(
"
UPDATE versions
SET release_channel = $1
SET version_type = $1
WHERE (id = $2)
",
channel as database::models::ids::ChannelId,
version_type.as_str(),
id as database::models::ids::VersionId,
)
.execute(&mut *transaction)