Batch inserts [MOD-555] (#726)

* Batch a bunch of inserts, but still more to do

* Insert many for clickhouse (+ tests)

* Batch the remaining ones except those requiring deduplication

* Risky dedups

* Bit o cleanup and formatting

* cargo sqlx prepare

* Add test around batch editing project categories

* Add struct to satisfy clippy

* Fix silly mistake that was caught by the tests!

* Leave room for growth in dummy_data
This commit is contained in:
Jackson Kruger
2023-10-11 13:32:58 -05:00
committed by GitHub
parent dfa43f3c5a
commit d92272ffa0
23 changed files with 1208 additions and 929 deletions

View File

@@ -81,19 +81,19 @@ impl Collection {
.execute(&mut *transaction)
.await?;
for project_id in self.projects.iter() {
sqlx::query!(
"
INSERT INTO collections_mods (collection_id, mod_id)
VALUES ($1, $2)
ON CONFLICT DO NOTHING
",
self.id as CollectionId,
*project_id as ProjectId,
)
.execute(&mut *transaction)
.await?;
}
let (collection_ids, project_ids): (Vec<_>, Vec<_>) =
self.projects.iter().map(|p| (self.id.0, p.0)).unzip();
sqlx::query!(
"
INSERT INTO collections_mods (collection_id, mod_id)
SELECT * FROM UNNEST($1::bigint[], $2::bigint[])
ON CONFLICT DO NOTHING
",
&collection_ids[..],
&project_ids[..],
)
.execute(&mut *transaction)
.await?;
Ok(())
}

View File

@@ -5,6 +5,7 @@ use crate::database::redis::RedisPool;
use crate::models::ids::base62_impl::{parse_base62, to_base62};
use crate::models::projects::{MonetizationStatus, ProjectStatus};
use chrono::{DateTime, Utc};
use itertools::Itertools;
use serde::{Deserialize, Serialize};
pub const PROJECTS_NAMESPACE: &str = "projects";
@@ -20,23 +21,25 @@ pub struct DonationUrl {
}
impl DonationUrl {
pub async fn insert_project(
&self,
pub async fn insert_many_projects(
donation_urls: Vec<Self>,
project_id: ProjectId,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<(), sqlx::error::Error> {
let (project_ids, platform_ids, urls): (Vec<_>, Vec<_>, Vec<_>) = donation_urls
.into_iter()
.map(|url| (project_id.0, url.platform_id.0, url.url))
.multiunzip();
sqlx::query!(
"
INSERT INTO mods_donations (
joining_mod_id, joining_platform_id, url
)
VALUES (
$1, $2, $3
)
SELECT * FROM UNNEST($1::bigint[], $2::int[], $3::varchar[])
",
project_id as ProjectId,
self.platform_id as DonationPlatformId,
self.url,
&project_ids[..],
&platform_ids[..],
&urls[..],
)
.execute(&mut *transaction)
.await?;
@@ -56,26 +59,76 @@ pub struct GalleryItem {
}
impl GalleryItem {
pub async fn insert(
&self,
pub async fn insert_many(
items: Vec<Self>,
project_id: ProjectId,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<(), sqlx::error::Error> {
let (project_ids, image_urls, featureds, titles, descriptions, orderings): (
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
) = items
.into_iter()
.map(|gi| {
(
project_id.0,
gi.image_url,
gi.featured,
gi.title,
gi.description,
gi.ordering,
)
})
.multiunzip();
sqlx::query!(
"
INSERT INTO mods_gallery (
mod_id, image_url, featured, title, description, ordering
)
VALUES (
$1, $2, $3, $4, $5, $6
)
SELECT * FROM UNNEST ($1::bigint[], $2::varchar[], $3::bool[], $4::varchar[], $5::varchar[], $6::bigint[])
",
project_id as ProjectId,
self.image_url,
self.featured,
self.title,
self.description,
self.ordering
&project_ids[..],
&image_urls[..],
&featureds[..],
&titles[..] as &[Option<String>],
&descriptions[..] as &[Option<String>],
&orderings[..]
)
.execute(&mut *transaction)
.await?;
Ok(())
}
}
#[derive(derive_new::new)]
pub struct ModCategory {
project_id: ProjectId,
category_id: CategoryId,
is_additional: bool,
}
impl ModCategory {
pub async fn insert_many(
items: Vec<Self>,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<(), DatabaseError> {
let (project_ids, category_ids, is_additionals): (Vec<_>, Vec<_>, Vec<_>) = items
.into_iter()
.map(|mc| (mc.project_id.0, mc.category_id.0, mc.is_additional))
.multiunzip();
sqlx::query!(
"
INSERT INTO mods_categories (joining_mod_id, joining_category_id, is_additional)
SELECT * FROM UNNEST ($1::bigint[], $2::int[], $3::bool[])
",
&project_ids[..],
&category_ids[..],
&is_additionals[..]
)
.execute(&mut *transaction)
.await?;
@@ -160,46 +213,35 @@ impl ProjectBuilder {
};
project_struct.insert(&mut *transaction).await?;
let ProjectBuilder {
donation_urls,
gallery_items,
categories,
additional_categories,
..
} = self;
for mut version in self.initial_versions {
version.project_id = self.project_id;
version.insert(&mut *transaction).await?;
}
for donation in self.donation_urls {
donation
.insert_project(self.project_id, &mut *transaction)
.await?;
}
for gallery in self.gallery_items {
gallery.insert(self.project_id, &mut *transaction).await?;
}
for category in self.categories {
sqlx::query!(
"
INSERT INTO mods_categories (joining_mod_id, joining_category_id, is_additional)
VALUES ($1, $2, FALSE)
",
self.project_id as ProjectId,
category as CategoryId,
)
.execute(&mut *transaction)
DonationUrl::insert_many_projects(donation_urls, self.project_id, &mut *transaction)
.await?;
}
for category in self.additional_categories {
sqlx::query!(
"
INSERT INTO mods_categories (joining_mod_id, joining_category_id, is_additional)
VALUES ($1, $2, TRUE)
",
self.project_id as ProjectId,
category as CategoryId,
GalleryItem::insert_many(gallery_items, self.project_id, &mut *transaction).await?;
let project_id = self.project_id;
let mod_categories = categories
.into_iter()
.map(|c| ModCategory::new(project_id, c, false))
.chain(
additional_categories
.into_iter()
.map(|c| ModCategory::new(project_id, c, true)),
)
.execute(&mut *transaction)
.await?;
}
.collect_vec();
ModCategory::insert_many(mod_categories, &mut *transaction).await?;
Project::update_game_versions(self.project_id, &mut *transaction).await?;
Project::update_loaders(self.project_id, &mut *transaction).await?;

View File

@@ -41,26 +41,61 @@ impl TeamBuilder {
.execute(&mut *transaction)
.await?;
for member in self.members {
let team_member_id = generate_team_member_id(&mut *transaction).await?;
sqlx::query!(
"
INSERT INTO team_members (id, team_id, user_id, role, permissions, organization_permissions, accepted, payouts_split, ordering)
VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9)
",
team_member_id as TeamMemberId,
team.id as TeamId,
member.user_id as UserId,
member.role,
member.permissions.bits() as i64,
member.organization_permissions.map(|p| p.bits() as i64),
member.accepted,
member.payouts_split,
member.ordering,
)
.execute(&mut *transaction)
.await?;
let mut team_member_ids = Vec::new();
for _ in self.members.iter() {
team_member_ids.push(generate_team_member_id(&mut *transaction).await?.0);
}
let TeamBuilder { members } = self;
let (
team_ids,
user_ids,
roles,
permissions,
organization_permissions,
accepteds,
payouts_splits,
orderings,
): (
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
) = members
.into_iter()
.map(|m| {
(
team.id.0,
m.user_id.0,
m.role,
m.permissions.bits() as i64,
m.organization_permissions.map(|p| p.bits() as i64),
m.accepted,
m.payouts_split,
m.ordering,
)
})
.multiunzip();
sqlx::query!(
"
INSERT INTO team_members (id, team_id, user_id, role, permissions, organization_permissions, accepted, payouts_split, ordering)
SELECT * FROM UNNEST ($1::int8[], $2::int8[], $3::int8[], $4::varchar[], $5::int8[], $6::int8[], $7::bool[], $8::numeric[], $9::int8[])
",
&team_member_ids[..],
&team_ids[..],
&user_ids[..],
&roles[..],
&permissions[..],
&organization_permissions[..] as &[Option<i64>],
&accepteds[..],
&payouts_splits[..],
&orderings[..],
)
.execute(&mut *transaction)
.await?;
Ok(team_id)
}

View File

@@ -90,22 +90,20 @@ impl ThreadBuilder {
.execute(&mut *transaction)
.await?;
for member in &self.members {
sqlx::query!(
"
INSERT INTO threads_members (
thread_id, user_id
)
VALUES (
$1, $2
)
",
thread_id as ThreadId,
*member as UserId,
let (thread_ids, members): (Vec<_>, Vec<_>) =
self.members.iter().map(|m| (thread_id.0, m.0)).unzip();
sqlx::query!(
"
INSERT INTO threads_members (
thread_id, user_id
)
.execute(&mut *transaction)
.await?;
}
SELECT * FROM UNNEST ($1::int8[], $2::int8[])
",
&thread_ids[..],
&members[..],
)
.execute(&mut *transaction)
.await?;
Ok(thread_id)
}

View File

@@ -39,12 +39,59 @@ pub struct DependencyBuilder {
}
impl DependencyBuilder {
pub async fn insert(
self,
pub async fn insert_many(
builders: Vec<Self>,
version_id: VersionId,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<(), DatabaseError> {
let project_id = if let Some(project_id) = self.project_id {
let mut project_ids = Vec::new();
for dependency in builders.iter() {
project_ids.push(
dependency
.try_get_project_id(transaction)
.await?
.map(|id| id.0),
);
}
let (version_ids, dependency_types, dependency_ids, filenames): (
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
) = builders
.into_iter()
.map(|d| {
(
version_id.0,
d.dependency_type,
d.version_id.map(|v| v.0),
d.file_name,
)
})
.multiunzip();
sqlx::query!(
"
INSERT INTO dependencies (dependent_id, dependency_type, dependency_id, mod_dependency_id, dependency_file_name)
SELECT * FROM UNNEST ($1::bigint[], $2::varchar[], $3::bigint[], $4::bigint[], $5::varchar[])
",
&version_ids[..],
&dependency_types[..],
&dependency_ids[..] as &[Option<i64>],
&project_ids[..] as &[Option<i64>],
&filenames[..] as &[Option<String>],
)
.execute(&mut *transaction)
.await?;
Ok(())
}
async fn try_get_project_id(
&self,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<Option<ProjectId>, DatabaseError> {
Ok(if let Some(project_id) = self.project_id {
Some(project_id)
} else if let Some(version_id) = self.version_id {
sqlx::query!(
@@ -58,23 +105,7 @@ impl DependencyBuilder {
.map(|x| ProjectId(x.mod_id))
} else {
None
};
sqlx::query!(
"
INSERT INTO dependencies (dependent_id, dependency_type, dependency_id, mod_dependency_id, dependency_file_name)
VALUES ($1, $2, $3, $4, $5)
",
version_id as VersionId,
self.dependency_type,
self.version_id.map(|x| x.0),
project_id.map(|x| x.0),
self.file_name,
)
.execute(&mut *transaction)
.await?;
Ok(())
})
}
}
@@ -89,42 +120,70 @@ pub struct VersionFileBuilder {
}
impl VersionFileBuilder {
pub async fn insert(
self,
pub async fn insert_many(
version_files: Vec<Self>,
version_id: VersionId,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<FileId, DatabaseError> {
let file_id = generate_file_id(&mut *transaction).await?;
let (file_ids, version_ids, urls, filenames, primary, sizes, file_types): (
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
Vec<_>,
) = version_files
.iter()
.map(|f| {
(
file_id.0,
version_id.0,
f.url.clone(),
f.filename.clone(),
f.primary,
f.size as i32,
f.file_type.map(|x| x.to_string()),
)
})
.multiunzip();
sqlx::query!(
"
INSERT INTO files (id, version_id, url, filename, is_primary, size, file_type)
VALUES ($1, $2, $3, $4, $5, $6, $7)
SELECT * FROM UNNEST($1::bigint[], $2::bigint[], $3::varchar[], $4::varchar[], $5::bool[], $6::integer[], $7::varchar[])
",
file_id as FileId,
version_id as VersionId,
self.url,
self.filename,
self.primary,
self.size as i32,
self.file_type.map(|x| x.as_str()),
&file_ids[..],
&version_ids[..],
&urls[..],
&filenames[..],
&primary[..],
&sizes[..],
&file_types[..] as &[Option<String>],
)
.execute(&mut *transaction)
.await?;
for hash in self.hashes {
sqlx::query!(
"
INSERT INTO hashes (file_id, algorithm, hash)
VALUES ($1, $2, $3)
",
file_id as FileId,
hash.algorithm,
hash.hash,
)
.execute(&mut *transaction)
.await?;
}
let (file_ids, algorithms, hashes): (Vec<_>, Vec<_>, Vec<_>) = version_files
.into_iter()
.flat_map(|f| {
f.hashes
.into_iter()
.map(|h| (file_id.0, h.algorithm, h.hash))
})
.multiunzip();
sqlx::query!(
"
INSERT INTO hashes (file_id, algorithm, hash)
SELECT * FROM UNNEST($1::bigint[], $2::varchar[], $3::bytea[])
",
&file_ids[..],
&algorithms[..],
&hashes[..],
)
.execute(&mut *transaction)
.await?;
Ok(file_id)
}
@@ -170,44 +229,94 @@ impl VersionBuilder {
.execute(&mut *transaction)
.await?;
for file in self.files {
file.insert(self.version_id, transaction).await?;
}
let VersionBuilder {
dependencies,
loaders,
game_versions,
files,
version_id,
..
} = self;
VersionFileBuilder::insert_many(files, self.version_id, transaction).await?;
for dependency in self.dependencies {
dependency.insert(self.version_id, transaction).await?;
}
DependencyBuilder::insert_many(dependencies, self.version_id, transaction).await?;
for loader in self.loaders.clone() {
sqlx::query!(
"
INSERT INTO loaders_versions (loader_id, version_id)
VALUES ($1, $2)
",
loader as LoaderId,
self.version_id as VersionId,
)
.execute(&mut *transaction)
.await?;
}
let loader_versions = loaders
.iter()
.map(|l| LoaderVersion::new(*l, version_id))
.collect_vec();
LoaderVersion::insert_many(loader_versions, &mut *transaction).await?;
for game_version in self.game_versions.clone() {
sqlx::query!(
"
INSERT INTO game_versions_versions (game_version_id, joining_version_id)
VALUES ($1, $2)
",
game_version as GameVersionId,
self.version_id as VersionId,
)
.execute(&mut *transaction)
.await?;
}
let game_version_versions = game_versions
.iter()
.map(|v| VersionVersion::new(*v, version_id))
.collect_vec();
VersionVersion::insert_many(game_version_versions, &mut *transaction).await?;
Ok(self.version_id)
}
}
#[derive(derive_new::new)]
pub struct LoaderVersion {
pub loader_id: LoaderId,
pub version_id: VersionId,
}
impl LoaderVersion {
pub async fn insert_many(
items: Vec<Self>,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<(), DatabaseError> {
let (loader_ids, version_ids): (Vec<_>, Vec<_>) = items
.iter()
.map(|l| (l.loader_id.0, l.version_id.0))
.unzip();
sqlx::query!(
"
INSERT INTO loaders_versions (loader_id, version_id)
SELECT * FROM UNNEST($1::integer[], $2::bigint[])
",
&loader_ids[..],
&version_ids[..],
)
.execute(&mut *transaction)
.await?;
Ok(())
}
}
#[derive(derive_new::new)]
pub struct VersionVersion {
pub game_version_id: GameVersionId,
pub joining_version_id: VersionId,
}
impl VersionVersion {
pub async fn insert_many(
items: Vec<Self>,
transaction: &mut sqlx::Transaction<'_, sqlx::Postgres>,
) -> Result<(), DatabaseError> {
let (game_version_ids, version_ids): (Vec<_>, Vec<_>) = items
.into_iter()
.map(|i| (i.game_version_id.0, i.joining_version_id.0))
.unzip();
sqlx::query!(
"
INSERT INTO game_versions_versions (game_version_id, joining_version_id)
SELECT * FROM UNNEST($1::integer[], $2::bigint[])
",
&game_version_ids[..],
&version_ids[..],
)
.execute(&mut *transaction)
.await?;
Ok(())
}
}
#[derive(Clone, Deserialize, Serialize)]
pub struct Version {
pub id: VersionId,