updated db to support state history

This commit is contained in:
2026-02-07 13:24:49 -05:00
parent 3dc5461783
commit d321c83f49
3 changed files with 114 additions and 0 deletions

View File

@@ -0,0 +1,53 @@
'use strict';
var dbm;
var type;
var seed;
var fs = require('fs');
var path = require('path');
var Promise;
/**
* We receive the dbmigrate dependency from dbmigrate initially.
* This enables us to not have to rely on NODE_PATH.
*/
exports.setup = function(options, seedLink) {
dbm = options.dbmigrate;
type = dbm.dataType;
seed = seedLink;
Promise = options.Promise;
};
exports.up = function(db) {
var filePath = path.join(__dirname, 'sqls', '20260204140912-state-history-suspensions-up.sql');
return new Promise( function( resolve, reject ) {
fs.readFile(filePath, {encoding: 'utf-8'}, function(err,data){
if (err) return reject(err);
console.log('received data: ' + data);
resolve(data);
});
})
.then(function(data) {
return db.runSql(data);
});
};
exports.down = function(db) {
var filePath = path.join(__dirname, 'sqls', '20260204140912-state-history-suspensions-down.sql');
return new Promise( function( resolve, reject ) {
fs.readFile(filePath, {encoding: 'utf-8'}, function(err,data){
if (err) return reject(err);
console.log('received data: ' + data);
resolve(data);
});
})
.then(function(data) {
return db.runSql(data);
});
};
exports._meta = {
"version": 1
};

View File

@@ -0,0 +1,14 @@
/* Replace with your SQL commands */
UPDATE members m
JOIN account_states s ON m.state_id = s.id
SET m.state_legacy = s.name;
ALTER TABLE members DROP FOREIGN KEY fk_members_state_id,
DROP INDEX idx_members_state_id,
DROP COLUMN state_id;
ALTER TABLE members
RENAME COLUMN state_legacy TO state;
DROP TABLE IF EXISTS member_state_history;
DROP TABLE IF EXISTS account_states;

View File

@@ -0,0 +1,47 @@
/* Replace with your SQL commands */
CREATE TABLE IF NOT EXISTS account_states (
id INT AUTO_INCREMENT PRIMARY KEY,
name VARCHAR(50) NOT NULL,
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
UNIQUE KEY uq_account_states_name (name)
);
INSERT IGNORE INTO account_states (name)
VALUES ('guest'),
('applicant'),
('member'),
('retired'),
('discharged'),
('suspended'),
('banned'),
('denied');
ALTER TABLE members
RENAME COLUMN state TO state_legacy;
ALTER TABLE members
ADD COLUMN state INT NOT NULL DEFAULT 1,
ADD INDEX idx_members_state (state),
ADD CONSTRAINT fk_members_state_id FOREIGN KEY (state) REFERENCES account_states(id);
CREATE TABLE IF NOT EXISTS member_state_history (
id INT AUTO_INCREMENT PRIMARY KEY,
member_id INT NOT NULL,
state_id INT NOT NULL,
reason VARCHAR(255),
created_by_id INT,
start_date DATE,
end_date DATE,
created_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_member_state_history_member_id (member_id),
CONSTRAINT fk_member_state_history_member FOREIGN KEY (member_id) REFERENCES members(id),
CONSTRAINT fk_member_state_type FOREIGN KEY (state_id) REFERENCES account_states(id),
CONSTRAINT fk_member_state_history_created_by FOREIGN KEY (created_by_id) REFERENCES members(id)
);
-- Convert member states to new system
UPDATE members m
JOIN account_states s ON m.state_legacy = s.name
SET m.state = s.id;