reminder-bot/migrations/20240210133900_macro_restructure.sql
2024-02-14 19:32:36 +00:00

54 lines
1.6 KiB
SQL

-- Add migration script here
CREATE TABLE command_macro (
id INT UNSIGNED AUTO_INCREMENT,
guild_id INT UNSIGNED NOT NULL,
name VARCHAR(100) NOT NULL,
description VARCHAR(100),
commands JSON NOT NULL,
FOREIGN KEY (guild_id) REFERENCES guilds(id) ON DELETE CASCADE,
PRIMARY KEY (id)
);
# New JSON structure is {command_name: "Remind", "<option name>": "<option value>", ...}
INSERT INTO command_macro (guild_id, description, name, commands)
SELECT
guild_id,
description,
name,
(
SELECT JSON_ARRAYAGG(
JSON_MERGE_PATCH(
'{}',
(
SELECT JSON_OBJECTAGG(t2.name, t2.value)
FROM JSON_TABLE(
JSON_ARRAY_APPEND(t1.options, '$', JSON_OBJECT('name', 'command_name', 'value', t1.command_name)),
'$[*]' COLUMNS (
name VARCHAR(64) PATH '$.name' ERROR ON ERROR,
value TEXT PATH '$.value' ERROR ON ERROR
)) AS t2
)
)
)
FROM macro m2
JOIN JSON_TABLE(
commands,
'$[*]' COLUMNS (
command_name VARCHAR(64) PATH '$.command_name' ERROR ON ERROR,
options JSON PATH '$.options' ERROR ON ERROR
)) AS t1
WHERE m1.id = m2.id
)
FROM macro m1;
SELECT id, JSON_OBJECT('command_name', t1.command_name), t1.options
FROM macro m1
JOIN JSON_TABLE(
commands,
'$[*]' COLUMNS (
command_name VARCHAR(64) PATH '$.command_name' ERROR ON ERROR,
options JSON PATH '$.options' ERROR ON ERROR
)) AS t1;