Side types overhaul (#762)

* side types overhaul

* fixes, fmt clippy

* migration fix for v3 bug

* fixed migration issues

* more tested migration changes

* fmt, clippy

* bump cicd

---------

Co-authored-by: Geometrically <18202329+Geometrically@users.noreply.github.com>
This commit is contained in:
Wyatt Verchere
2023-11-28 10:36:59 -08:00
committed by GitHub
parent fd18185ef0
commit f731c1080d
28 changed files with 957 additions and 555 deletions

View File

@@ -72,18 +72,20 @@ INSERT INTO loader_fields_loaders (loader_id, loader_field_id) SELECT l.id, lf.i
INSERT INTO loader_fields_loaders (loader_id, loader_field_id) SELECT l.id, lf.id FROM loaders l CROSS JOIN loader_fields lf WHERE lf.field = 'server_side' AND l.loader = ANY( ARRAY['forge', 'fabric', 'quilt', 'modloader','rift','liteloader', 'neoforge']);
INSERT INTO version_fields (version_id, field_id, enum_value)
SELECT v.id, 1, m.client_side
SELECT v.id, lf.id, lfev.id -- Note: bug fix/edited 2023-11-27
FROM versions v
INNER JOIN mods m ON v.mod_id = m.id
INNER JOIN loader_field_enum_values lfev ON m.client_side = lfev.original_id
WHERE client_side IS NOT NULL AND lfev.enum_id = 1;
CROSS JOIN loader_fields lf
WHERE client_side IS NOT NULL AND lfev.enum_id = 1 AND lf.field = 'client_side';
INSERT INTO version_fields (version_id, field_id, enum_value)
SELECT v.id, 1, m.server_side
SELECT v.id, lf.id, lfev.id -- Note: bug fix/edited 2023-11-27
FROM versions v
INNER JOIN mods m ON v.mod_id = m.id
INNER JOIN loader_field_enum_values lfev ON m.client_side = lfev.original_id
WHERE server_side IS NOT NULL AND lfev.enum_id = 1;
INNER JOIN loader_field_enum_values lfev ON m.server_side = lfev.original_id
CROSS JOIN loader_fields lf
WHERE server_side IS NOT NULL AND lfev.enum_id = 1 AND lf.field = 'server_side';
ALTER TABLE mods DROP COLUMN client_side;
ALTER TABLE mods DROP COLUMN server_side;
@@ -95,11 +97,13 @@ INSERT INTO loader_field_enum_values (original_id, enum_id, value, created, meta
SELECT id, 2, version, created, json_build_object('type', type, 'major', major) FROM game_versions;
INSERT INTO loader_fields (field, field_type, enum_type, optional, min_val) VALUES('game_versions', 'array_enum', 2, false, 0);
INSERT INTO loader_fields_loaders (loader_id, loader_field_id) SELECT l.id, lf.id FROM loaders l CROSS JOIN loader_fields lf WHERE lf.field = 'game_versions' AND l.loader = ANY( ARRAY['forge', 'fabric', 'quilt', 'modloader','rift','liteloader', 'neoforge']);
INSERT INTO version_fields(version_id, field_id, enum_value)
SELECT gvv.joining_version_id, 2, lfev.id
SELECT gvv.joining_version_id, lf.id, lfev.id
FROM game_versions_versions gvv INNER JOIN loader_field_enum_values lfev ON gvv.game_version_id = lfev.original_id
WHERE lfev.enum_id = 2;
CROSS JOIN loader_fields lf
WHERE lf.field = 'game_versions' AND lfev.enum_id = 2;
ALTER TABLE mods DROP COLUMN loaders;
ALTER TABLE mods DROP COLUMN game_versions;
@@ -108,12 +112,13 @@ DROP TABLE game_versions;
-- Convert project types
-- we are creating a new loader type- 'mrpack'- for minecraft modpacks
SELECT setval('loaders_id_seq', (SELECT MAX(id) FROM loaders) + 1, false);
INSERT INTO loaders (loader) VALUES ('mrpack');
-- For the loader 'mrpack', we create loader fields for every loader
-- That way we keep information like "this modpack is a fabric modpack"
INSERT INTO loader_field_enums (id, enum_name, hidable) VALUES (3, 'mrpack_loaders', true);
INSERT INTO loader_field_enum_values (original_id, enum_id, value) SELECT id, 2, loader FROM loaders WHERE loader != 'mrpack';
INSERT INTO loader_field_enum_values (original_id, enum_id, value) SELECT id, 3, loader FROM loaders WHERE loader != 'mrpack';
INSERT INTO loader_fields (field, field_type, enum_type, optional, min_val) VALUES('mrpack_loaders', 'array_enum', 3, false, 0);
INSERT INTO loader_fields_loaders (loader_id, loader_field_id)
SELECT l.id, lf.id FROM loaders l CROSS JOIN loader_fields lf WHERE lf.field = 'mrpack_loaders' AND l.loader = 'mrpack';
@@ -125,11 +130,31 @@ INNER JOIN mods m ON v.mod_id = m.id
INNER JOIN loaders_versions lv ON v.id = lv.version_id
INNER JOIN loaders l ON lv.loader_id = l.id
CROSS JOIN loader_fields lf
LEFT JOIN loader_field_enum_values lfev ON lf.enum_type = lfev.enum_id
LEFT JOIN loader_field_enum_values lfev ON lf.enum_type = lfev.enum_id AND lfev.original_id = l.id
WHERE m.project_type = (SELECT id FROM project_types WHERE name = 'modpack') AND lf.field = 'mrpack_loaders';
INSERT INTO loaders_project_types (joining_loader_id, joining_project_type_id) SELECT DISTINCT l.id, pt.id FROM loaders l CROSS JOIN project_types pt WHERE pt.name = 'modpack' AND l.loader = 'mrpack';
-- Set those versions to mrpack as their version
INSERT INTO loaders_versions (version_id, loader_id)
SELECT DISTINCT vf.version_id, l.id
FROM version_fields vf
LEFT JOIN loader_fields lf ON lf.id = vf.field_id
CROSS JOIN loaders l
WHERE lf.field = 'mrpack_loaders'
AND l.loader = 'mrpack'
ON CONFLICT DO NOTHING;
-- Delete the old versions that had mrpack added to them
DELETE FROM loaders_versions lv
WHERE lv.loader_id != (SELECT id FROM loaders WHERE loader = 'mrpack')
AND lv.version_id IN (
SELECT version_id
FROM loaders_versions
WHERE loader_id = (SELECT id FROM loaders WHERE loader = 'mrpack')
);
--- Non-mrpack loaders no longer support modpacks
DELETE FROM loaders_project_types WHERE joining_loader_id != (SELECT id FROM loaders WHERE loader = 'mrpack') AND joining_project_type_id = (SELECT id FROM project_types WHERE name = 'modpack');

View File

@@ -0,0 +1,96 @@
INSERT INTO loader_fields (field, field_type, optional) SELECT 'singleplayer', 'boolean', false;
INSERT INTO loader_fields (field, field_type, optional) SELECT 'client_and_server', 'boolean', false;
INSERT INTO loader_fields (field, field_type, optional) SELECT 'client_only', 'boolean', false;
INSERT INTO loader_fields (field, field_type, optional) SELECT 'server_only', 'boolean', false;
-- Create 4 temporary columns for the four booleans (makes queries easier)
ALTER TABLE versions ADD COLUMN singleplayer boolean;
ALTER TABLE versions ADD COLUMN client_and_server boolean;
ALTER TABLE versions ADD COLUMN client_only boolean;
ALTER TABLE versions ADD COLUMN server_only boolean;
-- Set singleplayer to be true if either client_side or server_side is 'required' OR 'optional'
UPDATE versions v SET singleplayer = true
FROM version_fields vf
INNER JOIN loader_fields lf ON vf.field_id = lf.id
INNER JOIN loader_field_enum_values lfev ON lf.enum_type = lfev.id AND vf.enum_value = lfev.id
WHERE v.id = vf.version_id
AND (lf.field = 'client_side' OR lf.field = 'server_side') AND (lfev.value = 'required' OR lfev.value = 'optional');
-- Set client and server to be true if either client_side or server_side is 'required' OR 'optional'
UPDATE versions v SET client_and_server = true
FROM version_fields vf
INNER JOIN loader_fields lf ON vf.field_id = lf.id
INNER JOIN loader_field_enum_values lfev ON lf.enum_type = lfev.id AND vf.enum_value = lfev.id
WHERE v.id = vf.version_id
AND (lf.field = 'client_side' OR lf.field = 'server_side') AND (lfev.value = 'required' OR lfev.value = 'optional');
-- Set client_only to be true if client_side is 'required' or 'optional', and server_side is 'optional', 'unsupported', or 'unknown'
UPDATE versions v SET client_only = true
FROM version_fields vf
INNER JOIN loader_fields lf ON vf.field_id = lf.id
INNER JOIN loader_field_enum_values lfev ON lf.enum_type = lfev.enum_id AND vf.enum_value = lfev.id
CROSS JOIN version_fields vf2
INNER JOIN loader_fields lf2 ON vf2.field_id = lf2.id
INNER JOIN loader_field_enum_values lfev2 ON lf2.enum_type = lfev2.enum_id AND vf2.enum_value = lfev2.id
WHERE v.id = vf.version_id AND v.id = vf2.version_id
AND lf.field = 'client_side' AND (lfev.value = 'required' OR lfev.value = 'optional')
AND lf2.field = 'server_side' AND (lfev2.value = 'optional' OR lfev2.value = 'unsupported' OR lfev2.value = 'unknown');
-- Set server_only to be true if server_side is 'required' or 'optional', and client_side is 'optional', 'unsupported', or 'unknown'
UPDATE versions v SET server_only = true
FROM version_fields vf
INNER JOIN loader_fields lf ON vf.field_id = lf.id
INNER JOIN loader_field_enum_values lfev ON lf.enum_type = lfev.enum_id AND vf.enum_value = lfev.id
CROSS JOIN version_fields vf2
INNER JOIN loader_fields lf2 ON vf2.field_id = lf2.id
INNER JOIN loader_field_enum_values lfev2 ON lf2.enum_type = lfev2.enum_id AND vf2.enum_value = lfev2.id
WHERE v.id = vf.version_id AND v.id = vf2.version_id
AND lf.field = 'server_side' AND (lfev.value = 'required' OR lfev.value = 'optional')
AND lf2.field = 'client_side' AND (lfev2.value = 'optional' OR lfev2.value = 'unsupported' OR lfev2.value = 'unknown');
-- Insert the values into the version_fields table
INSERT INTO version_fields (version_id, field_id, int_value)
SELECT v.id, lf.id, CASE WHEN v.singleplayer THEN 1 ELSE 0 END
FROM versions v
INNER JOIN loader_fields lf ON lf.field = 'singleplayer';
INSERT INTO version_fields (version_id, field_id, int_value)
SELECT v.id, lf.id, CASE WHEN v.client_and_server THEN 1 ELSE 0 END
FROM versions v
INNER JOIN loader_fields lf ON lf.field = 'client_and_server';
INSERT INTO version_fields (version_id, field_id, int_value)
SELECT v.id, lf.id, CASE WHEN v.client_only THEN 1 ELSE 0 END
FROM versions v
INNER JOIN loader_fields lf ON lf.field = 'client_only';
INSERT INTO version_fields (version_id, field_id, int_value)
SELECT v.id, lf.id, CASE WHEN v.server_only THEN 1 ELSE 0 END
FROM versions v
INNER JOIN loader_fields lf ON lf.field = 'server_only';
-- Drop the temporary columns
ALTER TABLE versions DROP COLUMN singleplayer;
ALTER TABLE versions DROP COLUMN client_and_server;
ALTER TABLE versions DROP COLUMN client_only;
ALTER TABLE versions DROP COLUMN server_only;
-- For each loader where loader_fields_loaders is 'client_side' or 'server_side', add the new fields
INSERT INTO loader_fields_loaders (loader_id, loader_field_id)
SELECT lfl.loader_id, lf.id
FROM loader_fields_loaders lfl
CROSS JOIN loader_fields lf
WHERE lfl.loader_field_id IN (SELECT id FROM loader_fields WHERE field = 'client_side' OR field = 'server_side')
AND lf.field IN ('singleplayer', 'client_and_server', 'client_only', 'server_only')
ON CONFLICT DO NOTHING;
-- Drop the old loader_fields_loaders entries
DELETE FROM loader_fields_loaders WHERE loader_field_id IN (SELECT id FROM loader_fields WHERE field = 'client_side' OR field = 'server_side');
-- Drop client_side and server_side loader fields
DELETE FROM version_fields WHERE field_id IN (SELECT id FROM loader_fields WHERE field = 'client_side' OR field = 'server_side');
DELETE FROM loader_field_enum_values WHERE id IN (SELECT enum_type FROM loader_fields WHERE field = 'client_side' OR field = 'server_side');
DELETE FROM loader_fields WHERE field = 'client_side' OR field = 'server_side';
DELETE FROM loader_field_enums WHERE id IN (SELECT enum_type FROM loader_fields WHERE field = 'side_types');

View File

@@ -1,45 +0,0 @@
-- Adds missing fields to loader_fields_loaders
INSERT INTO loader_fields_loaders (loader_id, loader_field_id)
SELECT l.id, lf.id FROM loaders l CROSS JOIN loader_fields lf WHERE lf.field = 'game_versions'
AND l.loader = ANY( ARRAY['forge', 'fabric', 'quilt', 'modloader','rift','liteloader', 'neoforge'])
ON CONFLICT (loader_id, loader_field_id) DO NOTHING;
-- Fixes mrpack variants being added to the wrong enum
-- Luckily, mrpack variants are the only ones set to 2 without metadata
UPDATE loader_field_enum_values SET enum_id = 3 WHERE enum_id = 2 AND metadata IS NULL;
-- Because it was mislabeled, version_fields for mrpack_loaders were set to null.
-- 1) Update version_fields corresponding to mrpack_loaders to the correct enum_value
UPDATE version_fields vf
SET enum_value = subquery.lfev_id
FROM (
SELECT vf.version_id, vf.field_id, lfev.id AS lfev_id
FROM version_fields vf
LEFT JOIN versions v ON v.id = vf.version_id
LEFT JOIN loaders_versions lv ON v.id = lv.version_id
LEFT JOIN loaders l ON l.id = lv.loader_id
LEFT JOIN loader_fields lf ON lf.id = vf.field_id
LEFT JOIN loader_field_enum_values lfev ON lfev.value = l.loader AND lf.enum_type = lfev.enum_id
WHERE lf.field = 'mrpack_loaders' AND vf.enum_value IS NULL
) AS subquery
WHERE vf.version_id = subquery.version_id AND vf.field_id = subquery.field_id;
-- 2) Set those versions to mrpack as their version
INSERT INTO loaders_versions (version_id, loader_id)
SELECT DISTINCT vf.version_id, l.id
FROM version_fields vf
LEFT JOIN loader_fields lf ON lf.id = vf.field_id
CROSS JOIN loaders l
WHERE lf.field = 'mrpack_loaders'
AND l.loader = 'mrpack'
ON CONFLICT DO NOTHING;
-- 3) Delete the old versions that had mrpack added to them
DELETE FROM loaders_versions lv
WHERE lv.loader_id != (SELECT id FROM loaders WHERE loader = 'mrpack')
AND lv.version_id IN (
SELECT version_id
FROM loaders_versions
WHERE loader_id = (SELECT id FROM loaders WHERE loader = 'mrpack')
);