feat(migrations): add initial migration setup and performance indexes
- Introduced .pgmrc.json and migrate.json for node-pg-migrate configuration. - Added multiple migration files to create performance indexes for tasks and related entities. - Implemented functions for optimized task sorting and manual progress tracking. - Updated package.json to include migration scripts and dependencies for node-pg-migrate. - Created README.md for migration guidelines and best practices.
This commit is contained in:
@@ -0,0 +1,149 @@
|
||||
/* eslint-disable camelcase */
|
||||
|
||||
exports.shorthands = undefined;
|
||||
|
||||
exports.up = pgm => {
|
||||
// Composite index for main task filtering
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_project_archived_parent
|
||||
ON tasks(project_id, archived, parent_task_id)
|
||||
WHERE archived = FALSE
|
||||
`);
|
||||
|
||||
// Index for status joins
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_status_project
|
||||
ON tasks(status_id, project_id)
|
||||
WHERE archived = FALSE
|
||||
`);
|
||||
|
||||
// Index for assignees lookup
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_assignees_task_member
|
||||
ON tasks_assignees(task_id, team_member_id)
|
||||
`);
|
||||
|
||||
// Index for phase lookup
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_phase_task_phase
|
||||
ON task_phase(task_id, phase_id)
|
||||
`);
|
||||
|
||||
// Index for subtask counting
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_parent_archived
|
||||
ON tasks(parent_task_id, archived)
|
||||
WHERE parent_task_id IS NOT NULL AND archived = FALSE
|
||||
`);
|
||||
|
||||
// Index for labels
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_labels_task_label
|
||||
ON task_labels(task_id, label_id)
|
||||
`);
|
||||
|
||||
// Index for comments count
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_comments_task
|
||||
ON task_comments(task_id)
|
||||
`);
|
||||
|
||||
// Index for attachments count
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_attachments_task
|
||||
ON task_attachments(task_id)
|
||||
`);
|
||||
|
||||
// Index for work log aggregation
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_work_log_task
|
||||
ON task_work_log(task_id)
|
||||
`);
|
||||
|
||||
// Index for subscribers check
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_subscribers_task
|
||||
ON task_subscribers(task_id)
|
||||
`);
|
||||
|
||||
// Index for dependencies check
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_dependencies_task
|
||||
ON task_dependencies(task_id)
|
||||
`);
|
||||
|
||||
// Additional performance indexes
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_dependencies_related
|
||||
ON task_dependencies(related_task_id)
|
||||
`);
|
||||
|
||||
// Index for custom column values
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_cc_column_values_task
|
||||
ON cc_column_values(task_id)
|
||||
`);
|
||||
|
||||
// Index for project members lookup
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_project_members_team_project
|
||||
ON project_members(team_member_id, project_id)
|
||||
`);
|
||||
|
||||
// Index for sorting
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_project_sort
|
||||
ON tasks(project_id, sort_order)
|
||||
WHERE archived = FALSE
|
||||
`);
|
||||
|
||||
// Index for roadmap sorting
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_project_roadmap_sort
|
||||
ON tasks(project_id, roadmap_sort_order)
|
||||
WHERE archived = FALSE
|
||||
`);
|
||||
|
||||
// Index for user lookup in team members
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_team_members_user_team
|
||||
ON team_members(user_id, team_id)
|
||||
WHERE active = TRUE
|
||||
`);
|
||||
|
||||
// Index for task statuses lookup
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_statuses_project_category
|
||||
ON task_statuses(project_id, category_id)
|
||||
`);
|
||||
|
||||
// Index for task priorities lookup
|
||||
pgm.sql(`
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_priority
|
||||
ON tasks(priority_id)
|
||||
WHERE archived = FALSE
|
||||
`);
|
||||
};
|
||||
|
||||
exports.down = pgm => {
|
||||
// Drop indexes in reverse order
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_tasks_priority');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_statuses_project_category');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_team_members_user_team');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_tasks_project_roadmap_sort');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_tasks_project_sort');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_project_members_team_project');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_cc_column_values_task');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_dependencies_related');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_dependencies_task');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_subscribers_task');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_work_log_task');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_attachments_task');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_comments_task');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_labels_task_label');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_tasks_parent_archived');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_task_phase_task_phase');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_tasks_assignees_task_member');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_tasks_status_project');
|
||||
pgm.sql('DROP INDEX IF EXISTS idx_tasks_project_archived_parent');
|
||||
};
|
||||
@@ -0,0 +1,183 @@
|
||||
/* eslint-disable camelcase */
|
||||
|
||||
exports.shorthands = undefined;
|
||||
|
||||
exports.up = pgm => {
|
||||
// Replace the optimized sort functions to avoid CTE usage in UPDATE statements
|
||||
pgm.createFunction(
|
||||
'handle_task_list_sort_between_groups_optimized',
|
||||
[
|
||||
{ name: '_from_index', type: 'integer' },
|
||||
{ name: '_to_index', type: 'integer' },
|
||||
{ name: '_task_id', type: 'uuid' },
|
||||
{ name: '_project_id', type: 'uuid' },
|
||||
{ name: '_batch_size', type: 'integer', default: 100 }
|
||||
],
|
||||
{ returns: 'void', language: 'plpgsql', replace: true },
|
||||
`
|
||||
DECLARE
|
||||
_offset INT := 0;
|
||||
_affected_rows INT;
|
||||
BEGIN
|
||||
-- PERFORMANCE OPTIMIZATION: Use direct updates without CTE in UPDATE
|
||||
IF (_to_index = -1)
|
||||
THEN
|
||||
_to_index = COALESCE((SELECT MAX(sort_order) + 1 FROM tasks WHERE project_id = _project_id), 0);
|
||||
END IF;
|
||||
|
||||
-- PERFORMANCE OPTIMIZATION: Batch updates for large datasets
|
||||
IF _to_index > _from_index
|
||||
THEN
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET sort_order = sort_order - 1
|
||||
WHERE project_id = _project_id
|
||||
AND sort_order > _from_index
|
||||
AND sort_order < _to_index
|
||||
AND sort_order > _offset
|
||||
AND sort_order <= _offset + _batch_size;
|
||||
|
||||
GET DIAGNOSTICS _affected_rows = ROW_COUNT;
|
||||
EXIT WHEN _affected_rows = 0;
|
||||
_offset := _offset + _batch_size;
|
||||
END LOOP;
|
||||
|
||||
UPDATE tasks SET sort_order = _to_index - 1 WHERE id = _task_id AND project_id = _project_id;
|
||||
END IF;
|
||||
|
||||
IF _to_index < _from_index
|
||||
THEN
|
||||
_offset := 0;
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET sort_order = sort_order + 1
|
||||
WHERE project_id = _project_id
|
||||
AND sort_order > _to_index
|
||||
AND sort_order < _from_index
|
||||
AND sort_order > _offset
|
||||
AND sort_order <= _offset + _batch_size;
|
||||
|
||||
GET DIAGNOSTICS _affected_rows = ROW_COUNT;
|
||||
EXIT WHEN _affected_rows = 0;
|
||||
_offset := _offset + _batch_size;
|
||||
END LOOP;
|
||||
|
||||
UPDATE tasks SET sort_order = _to_index + 1 WHERE id = _task_id AND project_id = _project_id;
|
||||
END IF;
|
||||
END
|
||||
`
|
||||
);
|
||||
|
||||
// Replace the second optimized sort function
|
||||
pgm.createFunction(
|
||||
'handle_task_list_sort_inside_group_optimized',
|
||||
[
|
||||
{ name: '_from_index', type: 'integer' },
|
||||
{ name: '_to_index', type: 'integer' },
|
||||
{ name: '_task_id', type: 'uuid' },
|
||||
{ name: '_project_id', type: 'uuid' },
|
||||
{ name: '_batch_size', type: 'integer', default: 100 }
|
||||
],
|
||||
{ returns: 'void', language: 'plpgsql', replace: true },
|
||||
`
|
||||
DECLARE
|
||||
_offset INT := 0;
|
||||
_affected_rows INT;
|
||||
BEGIN
|
||||
-- PERFORMANCE OPTIMIZATION: Batch updates for large datasets without CTE in UPDATE
|
||||
IF _to_index > _from_index
|
||||
THEN
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET sort_order = sort_order - 1
|
||||
WHERE project_id = _project_id
|
||||
AND sort_order > _from_index
|
||||
AND sort_order <= _to_index
|
||||
AND sort_order > _offset
|
||||
AND sort_order <= _offset + _batch_size;
|
||||
|
||||
GET DIAGNOSTICS _affected_rows = ROW_COUNT;
|
||||
EXIT WHEN _affected_rows = 0;
|
||||
_offset := _offset + _batch_size;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
IF _to_index < _from_index
|
||||
THEN
|
||||
_offset := 0;
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET sort_order = sort_order + 1
|
||||
WHERE project_id = _project_id
|
||||
AND sort_order >= _to_index
|
||||
AND sort_order < _from_index
|
||||
AND sort_order > _offset
|
||||
AND sort_order <= _offset + _batch_size;
|
||||
|
||||
GET DIAGNOSTICS _affected_rows = ROW_COUNT;
|
||||
EXIT WHEN _affected_rows = 0;
|
||||
_offset := _offset + _batch_size;
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
UPDATE tasks SET sort_order = _to_index WHERE id = _task_id AND project_id = _project_id;
|
||||
END
|
||||
`
|
||||
);
|
||||
|
||||
// Add simple bulk update function as alternative
|
||||
pgm.createFunction(
|
||||
'update_task_sort_orders_bulk',
|
||||
[{ name: '_updates', type: 'json' }],
|
||||
{ returns: 'void', language: 'plpgsql', replace: true },
|
||||
`
|
||||
DECLARE
|
||||
_update_record RECORD;
|
||||
BEGIN
|
||||
-- Simple approach: update each task's sort_order from the provided array
|
||||
FOR _update_record IN
|
||||
SELECT
|
||||
(item->>'task_id')::uuid as task_id,
|
||||
(item->>'sort_order')::int as sort_order,
|
||||
(item->>'status_id')::uuid as status_id,
|
||||
(item->>'priority_id')::uuid as priority_id,
|
||||
(item->>'phase_id')::uuid as phase_id
|
||||
FROM json_array_elements(_updates) as item
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET
|
||||
sort_order = _update_record.sort_order,
|
||||
status_id = COALESCE(_update_record.status_id, status_id),
|
||||
priority_id = COALESCE(_update_record.priority_id, priority_id)
|
||||
WHERE id = _update_record.task_id;
|
||||
|
||||
-- Handle phase updates separately since it's in a different table
|
||||
IF _update_record.phase_id IS NOT NULL THEN
|
||||
INSERT INTO task_phase (task_id, phase_id)
|
||||
VALUES (_update_record.task_id, _update_record.phase_id)
|
||||
ON CONFLICT (task_id) DO UPDATE SET phase_id = _update_record.phase_id;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END
|
||||
`
|
||||
);
|
||||
};
|
||||
|
||||
exports.down = pgm => {
|
||||
// Drop the functions if needed to rollback
|
||||
pgm.dropFunction('update_task_sort_orders_bulk', [{ name: '_updates', type: 'json' }], { ifExists: true });
|
||||
pgm.dropFunction('handle_task_list_sort_inside_group_optimized', [
|
||||
{ name: '_from_index', type: 'integer' },
|
||||
{ name: '_to_index', type: 'integer' },
|
||||
{ name: '_task_id', type: 'uuid' },
|
||||
{ name: '_project_id', type: 'uuid' },
|
||||
{ name: '_batch_size', type: 'integer' }
|
||||
], { ifExists: true });
|
||||
pgm.dropFunction('handle_task_list_sort_between_groups_optimized', [
|
||||
{ name: '_from_index', type: 'integer' },
|
||||
{ name: '_to_index', type: 'integer' },
|
||||
{ name: '_task_id', type: 'uuid' },
|
||||
{ name: '_project_id', type: 'uuid' },
|
||||
{ name: '_batch_size', type: 'integer' }
|
||||
], { ifExists: true });
|
||||
};
|
||||
@@ -0,0 +1,99 @@
|
||||
/* eslint-disable camelcase */
|
||||
|
||||
exports.shorthands = undefined;
|
||||
|
||||
exports.up = pgm => {
|
||||
// Add manual progress fields to tasks table
|
||||
pgm.addColumns('tasks', {
|
||||
manual_progress: {
|
||||
type: 'boolean',
|
||||
default: false,
|
||||
notNull: false
|
||||
},
|
||||
progress_value: {
|
||||
type: 'integer',
|
||||
default: null,
|
||||
notNull: false
|
||||
},
|
||||
weight: {
|
||||
type: 'integer',
|
||||
default: null,
|
||||
notNull: false
|
||||
}
|
||||
}, { ifNotExists: true });
|
||||
|
||||
// Update function to consider manual progress
|
||||
pgm.createFunction(
|
||||
'get_task_complete_ratio',
|
||||
[{ name: '_task_id', type: 'uuid' }],
|
||||
{ returns: 'json', language: 'plpgsql', replace: true },
|
||||
`
|
||||
DECLARE
|
||||
_parent_task_done FLOAT = 0;
|
||||
_sub_tasks_done FLOAT = 0;
|
||||
_sub_tasks_count FLOAT = 0;
|
||||
_total_completed FLOAT = 0;
|
||||
_total_tasks FLOAT = 0;
|
||||
_ratio FLOAT = 0;
|
||||
_is_manual BOOLEAN = FALSE;
|
||||
_manual_value INTEGER = NULL;
|
||||
BEGIN
|
||||
-- Check if manual progress is set
|
||||
SELECT manual_progress, progress_value
|
||||
FROM tasks
|
||||
WHERE id = _task_id
|
||||
INTO _is_manual, _manual_value;
|
||||
|
||||
-- If manual progress is enabled and has a value, use it directly
|
||||
IF _is_manual IS TRUE AND _manual_value IS NOT NULL THEN
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _manual_value,
|
||||
'total_completed', 0,
|
||||
'total_tasks', 0,
|
||||
'is_manual', TRUE
|
||||
);
|
||||
END IF;
|
||||
|
||||
-- Otherwise calculate automatically as before
|
||||
SELECT (CASE
|
||||
WHEN EXISTS(SELECT 1
|
||||
FROM tasks_with_status_view
|
||||
WHERE tasks_with_status_view.task_id = _task_id
|
||||
AND is_done IS TRUE) THEN 1
|
||||
ELSE 0 END)
|
||||
INTO _parent_task_done;
|
||||
SELECT COUNT(*) FROM tasks WHERE parent_task_id = _task_id AND archived IS FALSE INTO _sub_tasks_count;
|
||||
|
||||
SELECT COUNT(*)
|
||||
FROM tasks_with_status_view
|
||||
WHERE parent_task_id = _task_id
|
||||
AND is_done IS TRUE
|
||||
INTO _sub_tasks_done;
|
||||
|
||||
_total_completed = _parent_task_done + _sub_tasks_done;
|
||||
_total_tasks = _sub_tasks_count; -- +1 for the parent task
|
||||
|
||||
IF _total_tasks > 0 THEN
|
||||
_ratio = (_total_completed / _total_tasks) * 100;
|
||||
ELSE
|
||||
_ratio = _parent_task_done * 100;
|
||||
END IF;
|
||||
|
||||
RETURN JSON_BUILD_OBJECT(
|
||||
'ratio', _ratio,
|
||||
'total_completed', _total_completed,
|
||||
'total_tasks', _total_tasks,
|
||||
'is_manual', FALSE
|
||||
);
|
||||
END
|
||||
`
|
||||
);
|
||||
};
|
||||
|
||||
exports.down = pgm => {
|
||||
// Drop the function first (it depends on the columns)
|
||||
pgm.dropFunction('get_task_complete_ratio', [{ name: '_task_id', type: 'uuid' }], { ifExists: true });
|
||||
|
||||
// Remove the added columns
|
||||
pgm.dropColumns('tasks', ['manual_progress', 'progress_value', 'weight'], { ifExists: true });
|
||||
};
|
||||
@@ -0,0 +1,103 @@
|
||||
/* eslint-disable camelcase */
|
||||
|
||||
exports.shorthands = undefined;
|
||||
|
||||
exports.up = pgm => {
|
||||
// Add new sort order columns for different grouping types
|
||||
pgm.addColumns('tasks', {
|
||||
status_sort_order: {
|
||||
type: 'integer',
|
||||
default: 0,
|
||||
notNull: false
|
||||
},
|
||||
priority_sort_order: {
|
||||
type: 'integer',
|
||||
default: 0,
|
||||
notNull: false
|
||||
},
|
||||
phase_sort_order: {
|
||||
type: 'integer',
|
||||
default: 0,
|
||||
notNull: false
|
||||
},
|
||||
member_sort_order: {
|
||||
type: 'integer',
|
||||
default: 0,
|
||||
notNull: false
|
||||
}
|
||||
}, { ifNotExists: true });
|
||||
|
||||
// Initialize new columns with current sort_order values
|
||||
pgm.sql(`
|
||||
UPDATE tasks SET
|
||||
status_sort_order = sort_order,
|
||||
priority_sort_order = sort_order,
|
||||
phase_sort_order = sort_order,
|
||||
member_sort_order = sort_order
|
||||
WHERE status_sort_order = 0
|
||||
OR priority_sort_order = 0
|
||||
OR phase_sort_order = 0
|
||||
OR member_sort_order = 0
|
||||
`);
|
||||
|
||||
// Add constraints to ensure non-negative values
|
||||
pgm.addConstraint('tasks', 'tasks_status_sort_order_check', {
|
||||
check: 'status_sort_order >= 0'
|
||||
}, { ifNotExists: true });
|
||||
|
||||
pgm.addConstraint('tasks', 'tasks_priority_sort_order_check', {
|
||||
check: 'priority_sort_order >= 0'
|
||||
}, { ifNotExists: true });
|
||||
|
||||
pgm.addConstraint('tasks', 'tasks_phase_sort_order_check', {
|
||||
check: 'phase_sort_order >= 0'
|
||||
}, { ifNotExists: true });
|
||||
|
||||
pgm.addConstraint('tasks', 'tasks_member_sort_order_check', {
|
||||
check: 'member_sort_order >= 0'
|
||||
}, { ifNotExists: true });
|
||||
|
||||
// Add indexes for performance
|
||||
pgm.createIndex('tasks', ['project_id', 'status_sort_order'], {
|
||||
name: 'idx_tasks_status_sort_order',
|
||||
ifNotExists: true
|
||||
});
|
||||
|
||||
pgm.createIndex('tasks', ['project_id', 'priority_sort_order'], {
|
||||
name: 'idx_tasks_priority_sort_order',
|
||||
ifNotExists: true
|
||||
});
|
||||
|
||||
pgm.createIndex('tasks', ['project_id', 'phase_sort_order'], {
|
||||
name: 'idx_tasks_phase_sort_order',
|
||||
ifNotExists: true
|
||||
});
|
||||
|
||||
pgm.createIndex('tasks', ['project_id', 'member_sort_order'], {
|
||||
name: 'idx_tasks_member_sort_order',
|
||||
ifNotExists: true
|
||||
});
|
||||
|
||||
// Add column comments for documentation
|
||||
pgm.sql("COMMENT ON COLUMN tasks.status_sort_order IS 'Sort order when grouped by status'");
|
||||
pgm.sql("COMMENT ON COLUMN tasks.priority_sort_order IS 'Sort order when grouped by priority'");
|
||||
pgm.sql("COMMENT ON COLUMN tasks.phase_sort_order IS 'Sort order when grouped by phase'");
|
||||
pgm.sql("COMMENT ON COLUMN tasks.member_sort_order IS 'Sort order when grouped by members/assignees'");
|
||||
};
|
||||
|
||||
exports.down = pgm => {
|
||||
// Drop indexes
|
||||
pgm.dropIndex('tasks', ['project_id', 'member_sort_order'], { name: 'idx_tasks_member_sort_order', ifExists: true });
|
||||
pgm.dropIndex('tasks', ['project_id', 'phase_sort_order'], { name: 'idx_tasks_phase_sort_order', ifExists: true });
|
||||
pgm.dropIndex('tasks', ['project_id', 'priority_sort_order'], { name: 'idx_tasks_priority_sort_order', ifExists: true });
|
||||
pgm.dropIndex('tasks', ['project_id', 'status_sort_order'], { name: 'idx_tasks_status_sort_order', ifExists: true });
|
||||
|
||||
// Drop constraints
|
||||
pgm.dropConstraint('tasks', 'tasks_member_sort_order_check', { ifExists: true });
|
||||
pgm.dropConstraint('tasks', 'tasks_phase_sort_order_check', { ifExists: true });
|
||||
pgm.dropConstraint('tasks', 'tasks_priority_sort_order_check', { ifExists: true });
|
||||
pgm.dropConstraint('tasks', 'tasks_status_sort_order_check', { ifExists: true });
|
||||
|
||||
// Drop columns
|
||||
pgm.dropColumns('tasks', ['status_sort_order', 'priority_sort_order', 'phase_sort_order', 'member_sort_order'], { ifExists: true });
|
||||
};
|
||||
Reference in New Issue
Block a user