Modifies sql queries to use CTEs (#773)

* fixes huge slowodwn on version item

* changes!

* fixes, touch ups, indices

* clippy prepare
This commit is contained in:
Wyatt Verchere
2023-11-30 11:10:56 -08:00
committed by GitHub
parent ed33dd2127
commit 58093a9438
19 changed files with 957 additions and 549 deletions

View File

@@ -227,7 +227,9 @@ pub struct GameId(pub i32);
#[sqlx(transparent)]
pub struct DonationPlatformId(pub i32);
#[derive(Copy, Clone, Debug, Type, PartialEq, Eq, Hash, Serialize, Deserialize)]
#[derive(
Copy, Clone, Debug, Type, PartialEq, Eq, Hash, Serialize, Deserialize, PartialOrd, Ord,
)]
#[sqlx(transparent)]
pub struct VersionId(pub i64);
#[derive(Copy, Clone, Debug, Type, Serialize, Deserialize, PartialEq, Eq, Hash)]
@@ -278,7 +280,9 @@ pub struct SessionId(pub i64);
#[sqlx(transparent)]
pub struct ImageId(pub i64);
#[derive(Copy, Clone, Debug, Type, Serialize, Deserialize, Eq, PartialEq, Hash)]
#[derive(
Copy, Clone, Debug, Type, Serialize, Deserialize, Eq, PartialEq, Hash, PartialOrd, Ord,
)]
#[sqlx(transparent)]
pub struct LoaderFieldId(pub i32);

View File

@@ -1,4 +1,5 @@
use std::collections::HashMap;
use std::hash::Hasher;
use super::ids::*;
use super::DatabaseError;
@@ -248,14 +249,24 @@ pub struct LoaderFieldEnumValue {
pub metadata: serde_json::Value,
}
#[derive(Clone, Serialize, Deserialize, Debug, PartialEq, Eq)]
impl std::hash::Hash for LoaderFieldEnumValue {
fn hash<H: Hasher>(&self, state: &mut H) {
self.id.hash(state);
self.enum_id.hash(state);
self.value.hash(state);
self.ordering.hash(state);
self.created.hash(state);
}
}
#[derive(Clone, Serialize, Deserialize, Debug, PartialEq, Eq, Hash)]
pub struct VersionField {
pub version_id: VersionId,
pub field_id: LoaderFieldId,
pub field_name: String,
pub value: VersionFieldValue,
}
#[derive(Clone, Serialize, Deserialize, Debug, PartialEq, Eq)]
#[derive(Clone, Serialize, Deserialize, Debug, PartialEq, Eq, Hash)]
pub enum VersionFieldValue {
Integer(i32),
Text(String),
@@ -796,13 +807,18 @@ impl VersionField {
}
pub fn from_query_json(
version_id: i64,
loader_fields: Option<serde_json::Value>,
version_fields: Option<serde_json::Value>,
loader_field_enum_values: Option<serde_json::Value>,
allow_many: bool, // If true, will allow multiple values for a single singleton field, returning them as separate VersionFields
// allow_many = true, multiple Bools => two VersionFields of Bool
// allow_many = false, multiple Bools => error
// multiple Arraybools => 1 VersionField of ArrayBool
) -> Vec<VersionField> {
#[derive(Deserialize, Debug)]
struct JsonLoaderField {
version_id: i64,
lf_id: i32,
field: String,
field_type: String,
@@ -840,13 +856,12 @@ impl VersionField {
loader_field_enum_values
.and_then(|x| serde_json::from_value(x).ok())
.unwrap_or_default();
let version_id = VersionId(version_id);
query_loader_fields
.into_iter()
.filter_map(|q| {
.flat_map(|q| {
let loader_field_type = match LoaderFieldType::build(&q.field_type, q.enum_type) {
Some(lft) => lft,
None => return None,
None => return vec![],
};
let loader_field = LoaderField {
id: LoaderFieldId(q.lf_id),
@@ -856,6 +871,7 @@ impl VersionField {
min_val: q.min_val,
max_val: q.max_val,
};
let version_id = VersionId(q.version_id);
let values = query_version_field_combined
.iter()
.filter_map(|qvf| {
@@ -883,8 +899,18 @@ impl VersionField {
}
})
.collect::<Vec<_>>();
VersionField::build(loader_field, version_id, values).ok()
if allow_many {
VersionField::build_many(loader_field, version_id, values)
.unwrap_or_default()
.into_iter()
.unique()
.collect_vec()
} else {
match VersionField::build(loader_field, version_id, values) {
Ok(vf) => vec![vf],
Err(_) => vec![],
}
}
})
.collect()
}
@@ -902,6 +928,23 @@ impl VersionField {
value,
})
}
pub fn build_many(
loader_field: LoaderField,
version_id: VersionId,
query_version_fields: Vec<QueryVersionField>,
) -> Result<Vec<VersionField>, DatabaseError> {
let values = VersionFieldValue::build_many(&loader_field.field_type, query_version_fields)?;
Ok(values
.into_iter()
.map(|value| VersionField {
version_id,
field_id: loader_field.id,
field_name: loader_field.field.clone(),
value,
})
.collect())
}
}
impl VersionFieldValue {
@@ -982,25 +1025,56 @@ impl VersionFieldValue {
})
}
// Build from internal query data
// This encapsulates reundant behavior in db querie -> object conversions
// This will ensure that if multiple QueryVersionFields are provided, they can be combined into a single VersionFieldValue
// of the appropriate type (ie: false, false, true -> ArrayBoolean([false, false, true])) (and not just Boolean)
pub fn build(
field_type: &LoaderFieldType,
qvfs: Vec<QueryVersionField>,
) -> Result<VersionFieldValue, DatabaseError> {
let field_name = field_type.to_str();
let get_first = |qvfs: Vec<QueryVersionField>| -> Result<QueryVersionField, DatabaseError> {
if qvfs.len() > 1 {
return Err(DatabaseError::SchemaError(format!(
"Multiple fields for field {}",
field_name
)));
match field_type {
LoaderFieldType::Integer
| LoaderFieldType::Text
| LoaderFieldType::Boolean
| LoaderFieldType::Enum(_) => {
let mut fields = Self::build_many(field_type, qvfs)?;
if fields.len() > 1 {
return Err(DatabaseError::SchemaError(format!(
"Multiple fields for field {}",
field_type.to_str()
)));
}
fields.pop().ok_or_else(|| {
DatabaseError::SchemaError(format!(
"No version fields for field {}",
field_type.to_str()
))
})
}
qvfs.into_iter().next().ok_or_else(|| {
DatabaseError::SchemaError(format!("No version fields for field {}", field_name))
})
};
LoaderFieldType::ArrayInteger
| LoaderFieldType::ArrayText
| LoaderFieldType::ArrayBoolean
| LoaderFieldType::ArrayEnum(_) => {
let fields = Self::build_many(field_type, qvfs)?;
Ok(fields.into_iter().next().ok_or_else(|| {
DatabaseError::SchemaError(format!(
"No version fields for field {}",
field_type.to_str()
))
})?)
}
}
}
// Build from internal query data
// This encapsulates reundant behavior in db querie -> object conversions
// This allows for multiple fields to be built at once. If there are multiple fields,
// but the type only allows for a single field, then multiple VersionFieldValues will be returned
// If there are multiple fields, and the type allows for multiple fields, then a single VersionFieldValue will be returned (array.len == 1)
pub fn build_many(
field_type: &LoaderFieldType,
qvfs: Vec<QueryVersionField>,
) -> Result<Vec<VersionFieldValue>, DatabaseError> {
let field_name = field_type.to_str();
let did_not_exist_error = |field_name: &str, desired_field: &str| {
DatabaseError::SchemaError(format!(
"Field name {} for field {} in does not exist",
@@ -1009,39 +1083,61 @@ impl VersionFieldValue {
};
Ok(match field_type {
LoaderFieldType::Integer => VersionFieldValue::Integer(
get_first(qvfs)?
.int_value
.ok_or(did_not_exist_error(field_name, "int_value"))?,
),
LoaderFieldType::Text => VersionFieldValue::Text(
get_first(qvfs)?
.string_value
.ok_or(did_not_exist_error(field_name, "string_value"))?,
),
LoaderFieldType::Boolean => VersionFieldValue::Boolean(
get_first(qvfs)?
.int_value
.ok_or(did_not_exist_error(field_name, "int_value"))?
!= 0,
),
LoaderFieldType::ArrayInteger => VersionFieldValue::ArrayInteger(
LoaderFieldType::Integer => qvfs
.into_iter()
.map(|qvf| {
Ok(VersionFieldValue::Integer(
qvf.int_value
.ok_or(did_not_exist_error(field_name, "int_value"))?,
))
})
.collect::<Result<Vec<VersionFieldValue>, DatabaseError>>()?,
LoaderFieldType::Text => qvfs
.into_iter()
.map(|qvf| {
Ok::<VersionFieldValue, DatabaseError>(VersionFieldValue::Text(
qvf.string_value
.ok_or(did_not_exist_error(field_name, "string_value"))?,
))
})
.collect::<Result<Vec<VersionFieldValue>, DatabaseError>>()?,
LoaderFieldType::Boolean => qvfs
.into_iter()
.map(|qvf| {
Ok::<VersionFieldValue, DatabaseError>(VersionFieldValue::Boolean(
qvf.int_value
.ok_or(did_not_exist_error(field_name, "int_value"))?
!= 0,
))
})
.collect::<Result<Vec<VersionFieldValue>, DatabaseError>>()?,
LoaderFieldType::Enum(id) => qvfs
.into_iter()
.map(|qvf| {
Ok::<VersionFieldValue, DatabaseError>(VersionFieldValue::Enum(
*id,
qvf.enum_value
.ok_or(did_not_exist_error(field_name, "enum_value"))?,
))
})
.collect::<Result<Vec<VersionFieldValue>, DatabaseError>>()?,
LoaderFieldType::ArrayInteger => vec![VersionFieldValue::ArrayInteger(
qvfs.into_iter()
.map(|qvf| {
qvf.int_value
.ok_or(did_not_exist_error(field_name, "int_value"))
})
.collect::<Result<_, _>>()?,
),
LoaderFieldType::ArrayText => VersionFieldValue::ArrayText(
)],
LoaderFieldType::ArrayText => vec![VersionFieldValue::ArrayText(
qvfs.into_iter()
.map(|qvf| {
qvf.string_value
.ok_or(did_not_exist_error(field_name, "string_value"))
})
.collect::<Result<_, _>>()?,
),
LoaderFieldType::ArrayBoolean => VersionFieldValue::ArrayBoolean(
)],
LoaderFieldType::ArrayBoolean => vec![VersionFieldValue::ArrayBoolean(
qvfs.into_iter()
.map(|qvf| {
Ok::<bool, DatabaseError>(
@@ -1051,15 +1147,8 @@ impl VersionFieldValue {
)
})
.collect::<Result<_, _>>()?,
),
LoaderFieldType::Enum(id) => VersionFieldValue::Enum(
*id,
get_first(qvfs)?
.enum_value
.ok_or(did_not_exist_error(field_name, "enum_value"))?,
),
LoaderFieldType::ArrayEnum(id) => VersionFieldValue::ArrayEnum(
)],
LoaderFieldType::ArrayEnum(id) => vec![VersionFieldValue::ArrayEnum(
*id,
qvfs.into_iter()
.map(|qvf| {
@@ -1067,7 +1156,7 @@ impl VersionFieldValue {
.ok_or(did_not_exist_error(field_name, "enum_value"))
})
.collect::<Result<_, _>>()?,
),
)],
})
}

View File

@@ -1,3 +1,4 @@
use super::loader_fields::VersionField;
use super::{ids::*, User};
use crate::database::models;
use crate::database::models::DatabaseError;
@@ -565,8 +566,103 @@ impl Project {
.map(|x| x as i64)
.collect();
// TODO: Possible improvements to look into:
// - use multiple queries instead of CTES (for cleanliness?)
// - repeated joins to mods in separate CTEs- perhaps 1 CTE for mods and use later (in mods_gallery_json, mods_donations_json, etc.)
let db_projects: Vec<QueryProject> = sqlx::query!(
"
WITH version_fields_cte AS (
SELECT mod_id, version_id, field_id, int_value, enum_value, string_value
FROM mods m
INNER JOIN versions v ON m.id = v.mod_id
INNER JOIN version_fields vf ON v.id = vf.version_id
WHERE m.id = ANY($1) OR m.slug = ANY($2)
),
version_fields_json AS (
SELECT DISTINCT mod_id,
JSONB_AGG(
DISTINCT jsonb_build_object('version_id', version_id, 'field_id', field_id, 'int_value', int_value, 'enum_value', enum_value, 'string_value', string_value)
) version_fields_json
FROM version_fields_cte
GROUP BY mod_id
),
loader_fields_cte AS (
SELECT DISTINCT vf.mod_id, vf.version_id, lf.*, l.loader
FROM loader_fields lf
INNER JOIN version_fields_cte vf ON lf.id = vf.field_id
LEFT JOIN loaders_versions lv ON vf.version_id = lv.version_id
LEFT JOIN loaders l ON lv.loader_id = l.id
GROUP BY vf.mod_id, vf.version_id, lf.enum_type, lf.id, l.loader
),
loader_fields_json AS (
SELECT DISTINCT mod_id,
JSONB_AGG(
DISTINCT jsonb_build_object(
'version_id', lf.version_id,
'lf_id', id, 'loader_name', loader, 'field', field, 'field_type', field_type, 'enum_type', enum_type, 'min_val', min_val, 'max_val', max_val, 'optional', optional
)
) filter (where lf.id is not null) loader_fields_json
FROM loader_fields_cte lf
GROUP BY mod_id
),
loader_field_enum_values_json AS (
SELECT DISTINCT mod_id,
JSONB_AGG(
DISTINCT jsonb_build_object(
'id', lfev.id, 'enum_id', lfev.enum_id, 'value', lfev.value, 'ordering', lfev.ordering, 'created', lfev.created, 'metadata', lfev.metadata
)
) filter (where lfev.id is not null) loader_field_enum_values_json
FROM loader_field_enum_values lfev
INNER JOIN loader_fields_cte lf on lf.enum_type = lfev.enum_id
GROUP BY mod_id
),
versions_cte AS (
SELECT DISTINCT mod_id, v.id as id, date_published
FROM mods m
INNER JOIN versions v ON m.id = v.mod_id AND v.status = ANY($3)
WHERE m.id = ANY($1) OR m.slug = ANY($2)
),
versions_json AS (
SELECT DISTINCT mod_id,
JSONB_AGG(
DISTINCT jsonb_build_object(
'id', id, 'date_published', date_published
)
) filter (where id is not null) versions_json
FROM versions_cte
GROUP BY mod_id
),
loaders_cte AS (
SELECT DISTINCT mod_id, l.id as id, l.loader
FROM versions_cte
INNER JOIN loaders_versions lv ON versions_cte.id = lv.version_id
INNER JOIN loaders l ON lv.loader_id = l.id
),
mods_gallery_json AS (
SELECT DISTINCT mod_id,
JSONB_AGG(
DISTINCT jsonb_build_object(
'image_url', mg.image_url, 'featured', mg.featured, 'title', mg.title, 'description', mg.description, 'created', mg.created, 'ordering', mg.ordering
)
) filter (where image_url is not null) mods_gallery_json
FROM mods_gallery mg
INNER JOIN mods m ON mg.mod_id = m.id
WHERE m.id = ANY($1) OR m.slug = ANY($2)
GROUP BY mod_id
),
donations_json AS (
SELECT DISTINCT joining_mod_id as mod_id,
JSONB_AGG(
DISTINCT jsonb_build_object(
'platform_id', md.joining_platform_id, 'platform_short', dp.short, 'platform_name', dp.name,'url', md.url
)
) filter (where md.joining_platform_id is not null) donations_json
FROM mods_donations md
INNER JOIN mods m ON md.joining_mod_id = m.id AND m.id = ANY($1) OR m.slug = ANY($2)
INNER JOIN donation_platforms dp ON md.joining_platform_id = dp.id
GROUP BY mod_id
)
SELECT m.id id, m.title title, m.description description, m.downloads downloads, m.follows follows,
m.icon_url icon_url, m.body body, m.published published,
m.updated updated, m.approved approved, m.queued, m.status status, m.requested_status requested_status,
@@ -579,25 +675,29 @@ impl Project {
ARRAY_AGG(DISTINCT g.slug) filter (where g.slug is not null) games,
ARRAY_AGG(DISTINCT c.category) filter (where c.category is not null and mc.is_additional is false) categories,
ARRAY_AGG(DISTINCT c.category) filter (where c.category is not null and mc.is_additional is true) additional_categories,
JSONB_AGG(DISTINCT jsonb_build_object('id', v.id, 'date_published', v.date_published)) filter (where v.id is not null) versions,
JSONB_AGG(DISTINCT jsonb_build_object('image_url', mg.image_url, 'featured', mg.featured, 'title', mg.title, 'description', mg.description, 'created', mg.created, 'ordering', mg.ordering)) filter (where mg.image_url is not null) gallery,
JSONB_AGG(DISTINCT jsonb_build_object('platform_id', md.joining_platform_id, 'platform_short', dp.short, 'platform_name', dp.name,'url', md.url)) filter (where md.joining_platform_id is not null) donations
v.versions_json versions,
mg.mods_gallery_json gallery,
md.donations_json donations,
vf.version_fields_json version_fields,
lf.loader_fields_json loader_fields,
lfev.loader_field_enum_values_json loader_field_enum_values
FROM mods m
INNER JOIN threads t ON t.mod_id = m.id
LEFT JOIN mods_gallery mg ON mg.mod_id = m.id
LEFT JOIN mods_donations md ON md.joining_mod_id = m.id
LEFT JOIN donation_platforms dp ON md.joining_platform_id = dp.id
LEFT JOIN mods_gallery_json mg ON mg.mod_id = m.id
LEFT JOIN donations_json md ON md.mod_id = m.id
LEFT JOIN mods_categories mc ON mc.joining_mod_id = m.id
LEFT JOIN categories c ON mc.joining_category_id = c.id
LEFT JOIN versions v ON v.mod_id = m.id AND v.status = ANY($3)
LEFT JOIN loaders_versions lv ON lv.version_id = v.id
LEFT JOIN loaders l on lv.loader_id = l.id
LEFT JOIN versions_json v ON v.mod_id = m.id
LEFT JOIN loaders_cte l on l.mod_id = m.id
LEFT JOIN loaders_project_types lpt ON lpt.joining_loader_id = l.id
LEFT JOIN project_types pt ON pt.id = lpt.joining_project_type_id
LEFT JOIN loaders_project_types_games lptg ON lptg.loader_id = l.id AND lptg.project_type_id = pt.id
LEFT JOIN games g ON lptg.game_id = g.id
LEFT OUTER JOIN version_fields_json vf ON m.id = vf.mod_id
LEFT OUTER JOIN loader_fields_json lf ON m.id = lf.mod_id
LEFT OUTER JOIN loader_field_enum_values_json lfev ON m.id = lfev.mod_id
WHERE m.id = ANY($1) OR m.slug = ANY($2)
GROUP BY t.id, m.id;
GROUP BY t.id, m.id, version_fields_json, loader_fields_json, loader_field_enum_values_json, versions_json, mods_gallery_json, donations_json;
",
&project_ids_parsed,
&remaining_strings.into_iter().map(|x| x.to_string().to_lowercase()).collect::<Vec<_>>(),
@@ -677,6 +777,7 @@ impl Project {
donation_urls: serde_json::from_value(
m.donations.unwrap_or_default(),
).ok().unwrap_or_default(),
aggregate_version_fields: VersionField::from_query_json(m.loader_fields, m.version_fields, m.loader_field_enum_values, true),
thread_id: ThreadId(m.thread_id),
}}))
})
@@ -796,4 +897,5 @@ pub struct QueryProject {
pub donation_urls: Vec<DonationUrl>,
pub gallery_items: Vec<GalleryItem>,
pub thread_id: ThreadId,
pub aggregate_version_fields: Vec<VersionField>,
}

View File

@@ -528,47 +528,92 @@ impl Version {
if !version_ids_parsed.is_empty() {
let db_versions: Vec<QueryVersion> = sqlx::query!(
"
WITH version_fields_cte AS (
SELECT version_id, field_id, int_value, enum_value, string_value
FROM version_fields WHERE version_id = ANY($1)
),
version_fields_json AS (
SELECT DISTINCT version_id,
JSONB_AGG(
DISTINCT jsonb_build_object('field_id', field_id, 'int_value', int_value, 'enum_value', enum_value, 'string_value', string_value)
) version_fields_json
FROM version_fields_cte
GROUP BY version_id
),
loader_fields_cte AS (
SELECT DISTINCT vf.version_id, lf.*, l.loader
FROM loader_fields lf
INNER JOIN version_fields_cte vf ON lf.id = vf.field_id
LEFT JOIN loaders_versions lv ON vf.version_id = lv.version_id
LEFT JOIN loaders l ON lv.loader_id = l.id
GROUP BY vf.version_id, lf.enum_type, lf.id, l.loader
),
loader_fields_json AS (
SELECT DISTINCT version_id,
JSONB_AGG(
DISTINCT jsonb_build_object(
'version_id', lf.version_id,
'lf_id', id, 'loader_name', loader, 'field', field, 'field_type', field_type, 'enum_type', enum_type, 'min_val', min_val, 'max_val', max_val, 'optional', optional
)
) filter (where lf.id is not null) loader_fields_json
FROM loader_fields_cte lf
GROUP BY version_id
),
loader_field_enum_values_json AS (
SELECT DISTINCT version_id,
JSONB_AGG(
DISTINCT jsonb_build_object(
'id', lfev.id, 'enum_id', lfev.enum_id, 'value', lfev.value, 'ordering', lfev.ordering, 'created', lfev.created, 'metadata', lfev.metadata
)
) filter (where lfev.id is not null) loader_field_enum_values_json
FROM loader_field_enum_values lfev
INNER JOIN loader_fields_cte lf on lf.enum_type = lfev.enum_id
GROUP BY version_id
),
files_cte AS (
SELECT DISTINCT version_id, f.id, f.url, f.filename, f.is_primary, f.size, f.file_type
FROM files f
WHERE f.version_id = ANY($1)
),
files_json AS (
SELECT DISTINCT version_id,
JSONB_AGG(
DISTINCT jsonb_build_object('id', id, 'url', url, 'filename', filename, 'primary', is_primary, 'size', size, 'file_type', file_type)
) files_json
FROM files_cte lf
GROUP BY version_id
),
hashes_json AS (
SELECT DISTINCT version_id,
JSONB_AGG(
DISTINCT jsonb_build_object('algorithm', algorithm, 'hash', encode(hash, 'escape'), 'file_id', file_id)
) hashes_json
FROM hashes
INNER JOIN files_cte lf on lf.id = hashes.file_id
GROUP BY version_id
),
dependencies_json AS (
SELECT DISTINCT dependent_id as version_id,
JSONB_AGG(
DISTINCT jsonb_build_object('project_id', d.mod_dependency_id, 'version_id', d.dependency_id, 'dependency_type', d.dependency_type,'file_name', dependency_file_name)
) dependencies_json
FROM dependencies d
WHERE dependent_id = ANY($1)
GROUP BY version_id
)
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.date_published date_published, v.downloads downloads,
v.version_type version_type, v.featured featured, v.status status, v.requested_status requested_status, v.ordering ordering,
ARRAY_AGG(DISTINCT l.loader) filter (where l.loader is not null) loaders,
ARRAY_AGG(DISTINCT pt.name) filter (where pt.name is not null) project_types,
ARRAY_AGG(DISTINCT g.slug) filter (where g.slug is not null) games,
JSONB_AGG(DISTINCT jsonb_build_object('id', f.id, 'url', f.url, 'filename', f.filename, 'primary', f.is_primary, 'size', f.size, 'file_type', f.file_type)) filter (where f.id is not null) files,
JSONB_AGG(DISTINCT jsonb_build_object('algorithm', h.algorithm, 'hash', encode(h.hash, 'escape'), 'file_id', h.file_id)) filter (where h.hash is not null) hashes,
JSONB_AGG(DISTINCT jsonb_build_object('project_id', d.mod_dependency_id, 'version_id', d.dependency_id, 'dependency_type', d.dependency_type,'file_name', dependency_file_name)) filter (where d.dependency_type is not null) dependencies,
JSONB_AGG(
DISTINCT jsonb_build_object(
'field_id', vf.field_id,
'int_value', vf.int_value,
'enum_value', vf.enum_value,
'string_value', vf.string_value
)
) filter (where vf.field_id is not null) version_fields,
JSONB_AGG(
DISTINCT jsonb_build_object(
'lf_id', lf.id,
'loader_name', l.loader,
'field', lf.field,
'field_type', lf.field_type,
'enum_type', lf.enum_type,
'min_val', lf.min_val,
'max_val', lf.max_val,
'optional', lf.optional
)
) filter (where lf.id is not null) loader_fields,
JSONB_AGG(
DISTINCT jsonb_build_object(
'id', lfev.id,
'enum_id', lfev.enum_id,
'value', lfev.value,
'ordering', lfev.ordering,
'created', lfev.created,
'metadata', lfev.metadata
)
) filter (where lfev.id is not null) loader_field_enum_values
f.files_json files,
h.hashes_json hashes,
d.dependencies_json dependencies,
vf.version_fields_json version_fields,
lf.loader_fields_json loader_fields,
lfev.loader_field_enum_values_json loader_field_enum_values
FROM versions v
LEFT OUTER JOIN loaders_versions lv on v.id = lv.version_id
LEFT OUTER JOIN loaders l on lv.loader_id = l.id
@@ -576,16 +621,14 @@ impl Version {
LEFT JOIN project_types pt on lpt.joining_project_type_id = pt.id
LEFT OUTER JOIN loaders_project_types_games lptg on l.id = lptg.loader_id AND pt.id = lptg.project_type_id
LEFT JOIN games g on lptg.game_id = g.id
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
LEFT OUTER JOIN version_fields vf on v.id = vf.version_id
LEFT OUTER JOIN loader_fields lf on vf.field_id = lf.id
LEFT OUTER JOIN loader_field_enums lfe on lf.enum_type = lfe.id
LEFT OUTER JOIN loader_field_enum_values lfev on lfe.id = lfev.enum_id
LEFT OUTER JOIN files_json f on v.id = f.version_id
LEFT OUTER JOIN hashes_json h on v.id = h.version_id
LEFT OUTER JOIN dependencies_json d on v.id = d.version_id
LEFT OUTER JOIN version_fields_json vf ON v.id = vf.version_id
LEFT OUTER JOIN loader_fields_json lf ON v.id = lf.version_id
LEFT OUTER JOIN loader_field_enum_values_json lfev ON v.id = lfev.version_id
WHERE v.id = ANY($1)
GROUP BY v.id
GROUP BY v.id, vf.version_fields_json, lf.loader_fields_json, lfev.loader_field_enum_values_json, f.files_json, h.hashes_json, d.dependencies_json
ORDER BY v.ordering ASC NULLS LAST, v.date_published ASC;
",
&version_ids_parsed
@@ -676,7 +719,7 @@ impl Version {
files
},
version_fields: VersionField::from_query_json(v.id, v.loader_fields, v.version_fields, v.loader_field_enum_values),
version_fields: VersionField::from_query_json(v.loader_fields, v.version_fields, v.loader_field_enum_values, false),
loaders: v.loaders.unwrap_or_default(),
project_types: v.project_types.unwrap_or_default(),
games: v.games.unwrap_or_default(),