finalized migration scripts

This commit is contained in:
2026-01-25 20:14:24 -05:00
parent 7017c2427c
commit b4fcb1a366
3 changed files with 394 additions and 1 deletions

View File

@@ -787,6 +787,397 @@ DROP TABLE IF EXISTS `view_member_settings`;
CREATE VIEW `view_member_settings` AS select `m`.`id` AS `id`,`m`.`displayName` AS `displayName` from `members` `m`
;
-- --------------------------------------------------------
-- Host: iceberg-gaming.com
-- Server version: 10.6.5-MariaDB-log - mariadb.org binary distribution
-- Server OS: Win64
-- HeidiSQL Version: 12.14.0.7165
-- --------------------------------------------------------
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET NAMES utf8 */;
/*!50503 SET NAMES utf8mb4 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
-- --------------------------------------------------------
-- Host: iceberg-gaming.com
-- Server version: 10.6.5-MariaDB-log - mariadb.org binary distribution
-- Server OS: Win64
-- HeidiSQL Version: 12.14.0.7165
-- --------------------------------------------------------
/*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */;
/*!40101 SET NAMES utf8 */;
/*!50503 SET NAMES utf8mb4 */;
/*!40103 SET @OLD_TIME_ZONE=@@TIME_ZONE */;
/*!40103 SET TIME_ZONE='+00:00' */;
/*!40014 SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0 */;
/*!40101 SET @OLD_SQL_MODE=@@SQL_MODE, SQL_MODE='NO_AUTO_VALUE_ON_ZERO' */;
/*!40111 SET @OLD_SQL_NOTES=@@SQL_NOTES, SQL_NOTES=0 */;
-- Dumping structure for procedure milsim_website_development.sp_accept_new_recruit_validation
CREATE PROCEDURE `sp_accept_new_recruit_validation`(
IN `p_site_config_id` INT,
IN `p_member_id` INT,
IN `p_authorized_by_id` INT,
IN `p_created_by_id` INT
)
BEGIN
#-------------------------------------------------------------------
# VARIABLE DECLARATIONS
#-------------------------------------------------------------------
DECLARE v_application_unit_on_accept INT;
DECLARE v_application_rank_on_accept INT;
DECLARE v_application_status_on_accept INT;
DECLARE v_cfg_exists INT DEFAULT 0;
DECLARE v_member_exists INT DEFAULT 0;
DECLARE v_auth_exists INT DEFAULT 0;
DECLARE v_created_exists INT DEFAULT 0;
DECLARE v_msg TEXT;
#-------------------------------------------------------------------
# VALIDATE INPUT PARAMETERS
#-------------------------------------------------------------------
IF p_site_config_id IS NULL THEN
SET v_msg = 'ERROR 1001: p_site_config_id cannot be NULL';
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
IF p_member_id IS NULL THEN
SET v_msg = 'ERROR 1002: p_member_id cannot be NULL';
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
IF p_authorized_by_id IS NULL THEN
SET v_msg = 'ERROR 1003: p_authorized_by_id cannot be NULL';
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
IF p_created_by_id IS NULL THEN
SET v_msg = 'ERROR 1004: p_created_by_id cannot be NULL';
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
#-------------------------------------------------------------------
# VALIDATE FOREIGN KEYS FOR MEMBERS
#-------------------------------------------------------------------
SELECT COUNT(*) INTO v_member_exists
FROM members WHERE id = p_member_id;
IF v_member_exists = 0 THEN
SET v_msg = CONCAT_WS('', 'ERROR 1101: p_member_id ', p_member_id, ' does not exist');
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
SELECT COUNT(*) INTO v_auth_exists
FROM members WHERE id = p_authorized_by_id;
IF v_auth_exists = 0 THEN
SET v_msg = CONCAT_WS('', 'ERROR 1102: p_authorized_by_id ', p_authorized_by_id, ' does not exist');
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
SELECT COUNT(*) INTO v_created_exists
FROM members WHERE id = p_created_by_id;
IF v_created_exists = 0 THEN
SET v_msg = CONCAT_WS('', 'ERROR 1103: p_created_by_id ', p_created_by_id, ' does not exist');
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
#-------------------------------------------------------------------
# FETCH SITE CONFIG
#-------------------------------------------------------------------
SELECT application_unit_on_accept,
application_rank_on_accept,
application_status_on_accept
INTO v_application_unit_on_accept,
v_application_rank_on_accept,
v_application_status_on_accept
FROM site_config
WHERE id = p_site_config_id
LIMIT 1;
SELECT ROW_COUNT() INTO v_cfg_exists;
# Debugging: check the fetched values (you can remove this later)
SELECT v_application_unit_on_accept, v_application_rank_on_accept, v_application_status_on_accept;
IF v_cfg_exists = 0 THEN
SET v_msg = CONCAT_WS('', 'ERROR 1201: p_site_config_id ', p_site_config_id, ' not found');
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
#-------------------------------------------------------------------
# VALIDATE THAT CONFIG VALUES ARE NOT NULL
#-------------------------------------------------------------------
IF v_application_unit_on_accept IS NULL THEN
SET v_msg = 'ERROR 1202: v_application_unit_on_accept is NULL in site_config';
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
IF v_application_rank_on_accept IS NULL THEN
SET v_msg = 'ERROR 1203: v_application_rank_on_accept is NULL in site_config';
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
IF v_application_status_on_accept IS NULL THEN
SET v_msg = 'ERROR 1204: v_application_status_on_accept is NULL in site_config';
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
#-------------------------------------------------------------------
# VALIDATE CONFIG FOREIGN KEY REFERENCES
#-------------------------------------------------------------------
IF (SELECT COUNT(*) FROM units WHERE id = v_application_unit_on_accept) = 0 THEN
SET v_msg = CONCAT_WS('', 'ERROR 1301: v_application_unit_on_accept (',
v_application_unit_on_accept, ') does not reference a valid unit');
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
IF (SELECT COUNT(*) FROM ranks WHERE id = v_application_rank_on_accept) = 0 THEN
SET v_msg = CONCAT_WS('', 'ERROR 1302: v_application_rank_on_accept (',
v_application_rank_on_accept, ') does not reference a valid rank');
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
IF (SELECT COUNT(*) FROM statuses WHERE id = v_application_status_on_accept) = 0 THEN
SET v_msg = CONCAT_WS('', 'ERROR 1303: v_application_status_on_accept (',
v_application_status_on_accept, ') does not reference a valid status');
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = v_msg;
END IF;
#-------------------------------------------------------------------
# CALL SUB-PROCEDURES
#-------------------------------------------------------------------
CALL sp_update_member_rank(
p_member_id,
v_application_rank_on_accept,
p_authorized_by_id,
p_created_by_id,
'Application Accepted',
NOW()
);
CALL sp_update_member_status(
p_member_id,
v_application_status_on_accept,
p_authorized_by_id,
p_created_by_id,
'Application Accepted',
NOW()
);
CALL sp_update_member_unit(
p_member_id,
v_application_unit_on_accept,
p_authorized_by_id,
p_created_by_id,
'Application Accepted',
NOW()
);
END
;
-- Dumping structure for procedure milsim_website_development.sp_GetCalendarEventSignups
CREATE PROCEDURE `sp_GetCalendarEventSignups`(
IN `p_event_id` INT
)
BEGIN
SELECT
s.member_id,
s.status,
m.name AS member_name,
u.name AS unit_name
FROM calendar_events_signups s
LEFT JOIN members m
ON s.member_id = m.id
-- Keep member status logic
LEFT JOIN members_statuses memStat
ON memStat.member_id = s.member_id
AND memStat.created_at = (
SELECT MAX(ms.created_at)
FROM members_statuses ms
WHERE ms.member_id = s.member_id
)
-- Get member's current unit
LEFT JOIN members_unit mu
ON mu.member_id = s.member_id
AND mu.end_date IS NULL
LEFT JOIN units u
ON u.id = mu.unit_id
WHERE s.event_id = p_event_id;
END
;
-- Dumping structure for procedure milsim_website_development.sp_manual_update_report
CREATE PROCEDURE `sp_manual_update_report`(
IN `p_member_guilded_id_createdBy` VARCHAR(10),
IN `p_guilded_report_id` VARCHAR(50)
)
BEGIN
DECLARE v_member_id INT;
/* Get member ID from guilded_id */
SELECT id
INTO v_member_id
FROM members
WHERE guilded_id = p_member_guilded_id_createdBy
LIMIT 1;
/* Safety check */
IF v_member_id IS NULL THEN
SIGNAL SQLSTATE '45000'
SET MESSAGE_TEXT = 'Member with provided guilded_id not found';
END IF;
/* Update course events */
UPDATE course_events ce
JOIN courses c
ON ce.course_id = c.id
SET
ce.created_by = v_member_id,
ce.hasBookwork = c.hasBookwork,
ce.hasQual = c.hasQual,
ce.guilded_report_id = p_guilded_report_id
WHERE ce.guilded_report_id IS NULL
AND ce.deleted = 0;
END
;
-- Dumping structure for procedure milsim_website_development.sp_update_member_rank
CREATE PROCEDURE `sp_update_member_rank`(
IN `p_member_id` INT,
IN `p_rank_id` INT,
IN `p_authorized_by_id` INT,
IN `p_created_by_id` INT,
IN `p_reason` VARCHAR(50),
IN `p_start_date` DATETIME
)
BEGIN
DECLARE existing_rank_id INT DEFAULT NULL;
DECLARE existing_end_date DATETIME DEFAULT NULL;
-- Get the latest record for the member_id, if it exists
SELECT `rank_id`, `end_date`
INTO existing_rank_id, existing_end_date
FROM `members_ranks`
WHERE `member_id` = p_member_id
ORDER BY `start_date` DESC
LIMIT 1;
-- If no existing record is found, or the rank_id is different, proceed to insert a new record
IF existing_rank_id IS NULL OR existing_rank_id != p_rank_id OR existing_end_date IS NOT NULL THEN
-- Update the end_date of the latest record if its end_date is NULL (i.e., it's the active record)
IF existing_rank_id IS NOT NULL THEN
UPDATE `members_ranks`
SET `end_date` = p_start_date
WHERE `member_id` = p_member_id AND `end_date` IS NULL;
END IF;
-- Insert a new record for the rank_id
INSERT INTO `members_ranks` (`member_id`, `rank_id`, `authorized_by_id`, `created_by_id`, `reason`, `start_date`, `created_at`, `updated_at`)
VALUES (p_member_id, p_rank_id, p_authorized_by_id, p_created_by_id, p_reason, p_start_date, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP);
END IF;
END
;
-- Dumping structure for procedure milsim_website_development.sp_update_member_status
CREATE PROCEDURE `sp_update_member_status`(
IN `p_member_id` INT,
IN `p_status_id` INT,
IN `p_authorized_by_id` INT,
IN `p_created_by_id` INT,
IN `p_reason` VARCHAR(50),
IN `p_start_date` DATETIME
)
BEGIN
DECLARE existing_status_id INT DEFAULT NULL;
DECLARE existing_end_date DATETIME DEFAULT NULL;
-- Get the latest record for the member_id, if it exists
SELECT `status_id`, `end_date`
INTO existing_status_id, existing_end_date
FROM `members_statuses`
WHERE `member_id` = p_member_id
ORDER BY `start_date` DESC
LIMIT 1;
-- If no existing record is found, or the status_id is different, proceed to insert a new record
IF existing_status_id IS NULL OR existing_status_id != p_status_id OR existing_end_date IS NOT NULL THEN
-- Update the end_date of the latest record if its end_date is NULL (i.e., it's the active record)
IF existing_status_id IS NOT NULL THEN
UPDATE `members_statuses`
SET `end_date` = p_start_date
WHERE `member_id` = p_member_id AND `end_date` IS NULL;
END IF;
-- Insert a new record for the status_id
INSERT INTO `members_statuses` (`member_id`, `status_id`, `authorized_by_id`, `created_by_id`, `reason`, `start_date`, `created_at`, `updated_at`)
VALUES (p_member_id, p_status_id, p_authorized_by_id, p_created_by_id, p_reason, p_start_date, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP);
END IF;
END;
-- Dumping structure for procedure milsim_website_development.sp_update_member_unit
CREATE PROCEDURE `sp_update_member_unit`(
IN `p_member_id` INT,
IN `p_unit_id` INT,
IN `p_authorized_by_id` INT,
IN `p_created_by_id` INT,
IN `p_reason` VARCHAR(50),
IN `p_start_date` DATETIME
)
BEGIN
DECLARE existing_unit_id INT DEFAULT NULL;
DECLARE existing_end_date DATETIME DEFAULT NULL;
-- Get the latest record for the member_id, if it exists
SELECT `unit_id`, `end_date`
INTO existing_unit_id, existing_end_date
FROM `members_unit`
WHERE `member_id` = p_member_id
ORDER BY `start_date` DESC
LIMIT 1;
-- If no existing record is found, or the unit_id is different, proceed to insert a new record
IF existing_unit_id IS NULL OR existing_unit_id != p_unit_id OR existing_end_date IS NOT NULL THEN
-- Update the end_date of the latest record if its end_date is NULL (i.e., it's the active record)
IF existing_unit_id IS NOT NULL THEN
UPDATE `members_unit`
SET `end_date` = p_start_date
WHERE `member_id` = p_member_id AND `end_date` IS NULL;
END IF;
-- Insert a new record for the unit_id
INSERT INTO `members_unit` (`member_id`, `unit_id`, `authorized_by_id`, `created_by_id`, `reason`, `start_date`, `created_at`, `updated_at`)
VALUES (p_member_id, p_unit_id, p_authorized_by_id, p_created_by_id, p_reason, p_start_date, CURRENT_TIMESTAMP, CURRENT_TIMESTAMP);
END IF;
END
;
/*!40103 SET TIME_ZONE=IFNULL(@OLD_TIME_ZONE, 'system') */;
/*!40101 SET SQL_MODE=IFNULL(@OLD_SQL_MODE, '') */;
/*!40014 SET FOREIGN_KEY_CHECKS=IFNULL(@OLD_FOREIGN_KEY_CHECKS, 1) */;