Füge Spalte product_quality zur Tabelle stock hinzu und erstelle Migration für weather_type_id in production
This commit is contained in:
@@ -8,29 +8,87 @@ module.exports = {
|
||||
ADD COLUMN IF NOT EXISTS character_name text;
|
||||
`);
|
||||
|
||||
// 2) Create helper function to populate character_name from character_id
|
||||
// 1b) Add character_id column so triggers and application can set a reference
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_log.notification
|
||||
ADD COLUMN IF NOT EXISTS character_id integer;
|
||||
`);
|
||||
|
||||
// Create an index on character_id to speed lookups (if not exists)
|
||||
await queryInterface.sequelize.query(`
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace
|
||||
WHERE c.relkind = 'i' AND c.relname = 'idx_notification_character_id' AND n.nspname = 'falukant_log'
|
||||
) THEN
|
||||
CREATE INDEX idx_notification_character_id ON falukant_log.notification (character_id);
|
||||
END IF;
|
||||
END$$;
|
||||
`);
|
||||
|
||||
// 2) Create helper function to populate character_name from character_id or user_id
|
||||
// - Resolve name via character_id if present
|
||||
// - Fallback to a character for the same user_id when character_id is NULL
|
||||
// - Only set NEW.character_name when the column exists and is NULL
|
||||
await queryInterface.sequelize.query(`
|
||||
CREATE OR REPLACE FUNCTION falukant_log.populate_notification_character_name()
|
||||
RETURNS TRIGGER AS $function$
|
||||
DECLARE
|
||||
v_first_name TEXT;
|
||||
v_last_name TEXT;
|
||||
v_char_id INTEGER;
|
||||
v_column_exists BOOLEAN;
|
||||
BEGIN
|
||||
IF NEW.character_name IS NULL AND NEW.character_id IS NOT NULL THEN
|
||||
-- check if target column exists in the notification table
|
||||
SELECT EXISTS(
|
||||
SELECT 1 FROM information_schema.columns
|
||||
WHERE table_schema = 'falukant_log' AND table_name = 'notification' AND column_name = 'character_name'
|
||||
) INTO v_column_exists;
|
||||
|
||||
IF NOT v_column_exists THEN
|
||||
-- Nothing to do when target column absent
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
-- only populate when column is NULL
|
||||
IF NEW.character_name IS NOT NULL THEN
|
||||
RETURN NEW;
|
||||
END IF;
|
||||
|
||||
-- prefer explicit character_id
|
||||
v_char_id := NEW.character_id;
|
||||
|
||||
-- when character_id is null, try to find a character for the user_id
|
||||
IF v_char_id IS NULL AND NEW.user_id IS NOT NULL THEN
|
||||
-- choose a representative character: the one with highest id for this user (change if different policy required)
|
||||
SELECT id INTO v_char_id
|
||||
FROM falukant_data.character
|
||||
WHERE user_id = NEW.user_id
|
||||
ORDER BY id DESC
|
||||
LIMIT 1;
|
||||
END IF;
|
||||
|
||||
IF v_char_id IS NOT NULL THEN
|
||||
SELECT pf.name, pl.name
|
||||
INTO v_first_name, v_last_name
|
||||
FROM falukant_data.character c
|
||||
LEFT JOIN falukant_predefine.firstname pf ON pf.id = c.first_name
|
||||
LEFT JOIN falukant_predefine.lastname pl ON pl.id = c.last_name
|
||||
WHERE c.id = NEW.character_id;
|
||||
LEFT JOIN falukant_predefine.lastname pl ON pl.id = c.last_name
|
||||
WHERE c.id = v_char_id;
|
||||
|
||||
IF v_first_name IS NOT NULL OR v_last_name IS NOT NULL THEN
|
||||
NEW.character_name := COALESCE(v_first_name, '') || CASE WHEN v_first_name IS NOT NULL AND v_last_name IS NOT NULL THEN ' ' ELSE '' END || COALESCE(v_last_name, '');
|
||||
ELSE
|
||||
-- Fallback to placeholder with id
|
||||
NEW.character_name := ('#' || NEW.character_id::text);
|
||||
NEW.character_name := ('#' || v_char_id::text);
|
||||
END IF;
|
||||
ELSE
|
||||
-- last resort fallback: use user_id as identifier if present
|
||||
IF NEW.user_id IS NOT NULL THEN
|
||||
NEW.character_name := ('#u' || NEW.user_id::text);
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$function$ LANGUAGE plpgsql;
|
||||
@@ -53,9 +111,25 @@ module.exports = {
|
||||
await queryInterface.sequelize.query(`
|
||||
DROP FUNCTION IF EXISTS falukant_log.populate_notification_character_name();
|
||||
`);
|
||||
await queryInterface.sequelize.query(`
|
||||
-- drop index if exists
|
||||
DO $$
|
||||
BEGIN
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace
|
||||
WHERE c.relkind = 'i' AND c.relname = 'idx_notification_character_id' AND n.nspname = 'falukant_log'
|
||||
) THEN
|
||||
EXECUTE 'DROP INDEX falukant_log.idx_notification_character_id';
|
||||
END IF;
|
||||
END$$;
|
||||
`);
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_log.notification
|
||||
DROP COLUMN IF EXISTS character_name;
|
||||
`);
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_log.notification
|
||||
DROP COLUMN IF EXISTS character_id;
|
||||
`);
|
||||
}
|
||||
};
|
||||
|
||||
@@ -0,0 +1,68 @@
|
||||
"use strict";
|
||||
|
||||
module.exports = {
|
||||
async up(queryInterface, Sequelize) {
|
||||
// Add nullable weather_type_id column
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_data.production
|
||||
ADD COLUMN IF NOT EXISTS weather_type_id integer;
|
||||
`);
|
||||
|
||||
// Add foreign key constraint if not exists
|
||||
await queryInterface.sequelize.query(`
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM information_schema.table_constraints tc
|
||||
JOIN information_schema.key_column_usage kcu ON kcu.constraint_name = tc.constraint_name AND kcu.constraint_schema = tc.constraint_schema
|
||||
WHERE tc.constraint_type = 'FOREIGN KEY'
|
||||
AND tc.constraint_schema = 'falukant_data'
|
||||
AND tc.table_name = 'production'
|
||||
AND kcu.column_name = 'weather_type_id'
|
||||
) THEN
|
||||
ALTER TABLE falukant_data.production
|
||||
ADD CONSTRAINT fk_production_weather_type
|
||||
FOREIGN KEY (weather_type_id) REFERENCES falukant_type.weather(id);
|
||||
END IF;
|
||||
END$$;
|
||||
`);
|
||||
|
||||
// create index to speed lookups
|
||||
await queryInterface.sequelize.query(`
|
||||
DO $$
|
||||
BEGIN
|
||||
IF NOT EXISTS (
|
||||
SELECT 1 FROM pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace
|
||||
WHERE c.relkind = 'i' AND c.relname = 'idx_production_weather_type_id' AND n.nspname = 'falukant_data'
|
||||
) THEN
|
||||
CREATE INDEX idx_production_weather_type_id ON falukant_data.production (weather_type_id);
|
||||
END IF;
|
||||
END$$;
|
||||
`);
|
||||
},
|
||||
|
||||
async down(queryInterface, Sequelize) {
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_data.production
|
||||
DROP CONSTRAINT IF EXISTS fk_production_weather_type;
|
||||
`);
|
||||
|
||||
await queryInterface.sequelize.query(`
|
||||
DO $$
|
||||
BEGIN
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM pg_class c JOIN pg_namespace n ON n.oid = c.relnamespace
|
||||
WHERE c.relkind = 'i' AND c.relname = 'idx_production_weather_type_id' AND n.nspname = 'falukant_data'
|
||||
) THEN
|
||||
EXECUTE 'DROP INDEX falukant_data.idx_production_weather_type_id';
|
||||
END IF;
|
||||
END$$;
|
||||
`);
|
||||
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_data.production
|
||||
DROP COLUMN IF EXISTS weather_type_id;
|
||||
`);
|
||||
}
|
||||
};
|
||||
@@ -0,0 +1,17 @@
|
||||
"use strict";
|
||||
|
||||
module.exports = {
|
||||
async up(queryInterface, Sequelize) {
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_data.stock
|
||||
ADD COLUMN IF NOT EXISTS product_quality integer;
|
||||
`);
|
||||
},
|
||||
|
||||
async down(queryInterface, Sequelize) {
|
||||
await queryInterface.sequelize.query(`
|
||||
ALTER TABLE IF EXISTS falukant_data.stock
|
||||
DROP COLUMN IF EXISTS product_quality;
|
||||
`);
|
||||
}
|
||||
};
|
||||
Reference in New Issue
Block a user