Skip to content
Snippets Groups Projects
Commit abd61039 authored by Jared Hancock's avatar Jared Hancock
Browse files

Merge ticket thread tables into one (2 of 2)

Add SQL patch file and update the main install SQL (MySQL) script to
transfer messages, responses, and notes into the new ticket_thread table.
For new installations, transfer is not necessary because there are no
messages
parent 1899a6c6
No related branches found
No related tags found
No related merge requests found
/**
* Merge ticket thread tables into one
*
* Replace the ticket_{message,response,note} tables with a single
* ticket_thread table that will contain data for all three current message
* types. This simplifies much of the ticket thread code and paves the way
* for other types of messages in the future.
*
* This patch automagically moves the data from the three federated tables
* into the one combined table.
*/
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_thread`;
CREATE TABLE `%TABLE_PREFIX%ticket_thread` (
`id` int(11) unsigned NOT NULL auto_increment,
`pid` int(11) unsigned NOT NULL default '0',
`ticket_id` int(11) unsigned NOT NULL default '0',
`staff_id` int(11) unsigned NOT NULL default '0',
`thread_type` enum('M','R','N') NOT NULL,
`poster` varchar(128) NOT NULL default '',
`source` varchar(32) NOT NULL default '',
`title` varchar(255),
`body` text NOT NULL,
`ip_address` varchar(64) NOT NULL default '',
`created` datetime NOT NULL,
`updated` datetime NOT NULL,
-- Temporary columns for conversion
`old_pk` int(11) unsigned NOT NULL,
`old_pid` int(11) unsigned,
PRIMARY KEY (`id`),
KEY `ticket_id` (`ticket_id`),
KEY `staff_id` (`staff_id`),
FULLTEXT KEY `body` (`body`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_email_info`;
CREATE TABLE `%TABLE_PREFIX%ticket_email_info` (
`message_id` int(11) unsigned NOT NULL,
`email_mid` varchar(255) NOT NULL,
`headers` text,
KEY `message_id` (`email_mid`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
-- Transfer messages
INSERT INTO `%TABLE_PREFIX%ticket_thread`
(`ticket_id`, `thread_type`, `body`, `ip_address`,
`created`, `updated`, `old_pk`)
SELECT `ticket_id`, 'M', `message`, `ip_address`,
`created`, COALESCE(`updated`, NOW()), `msg_id`
FROM `%TABLE_PREFIX%ticket_message`;
-- Transfer responses
INSERT INTO `%TABLE_PREFIX%ticket_thread`
(`ticket_id`, `staff_id`, `thread_type`, `poster`, `body`, `ip_address`,
`created`, `updated`, `old_pk`, `old_pid`)
SELECT `ticket_id`, `staff_id`, 'R', `staff_name`, `response`, `ip_address`,
`created`, COALESCE(`updated`, NOW()), `response_id`, `msg_id`
FROM `%TABLE_PREFIX%ticket_response`;
-- Connect responses to (new) messages
CREATE TABLE `%TABLE_PREFIX%T_resp_links`
SELECT `id`, `old_pk`, `old_pid` FROM `%TABLE_PREFIX%ticket_thread`;
UPDATE `%TABLE_PREFIX%ticket_thread`
SET `pid` = ( SELECT T2.`id` FROM `%TABLE_PREFIX%T_resp_links` T2
WHERE `old_pid` = T2.`old_pk` )
WHERE `thread_type` = 'R'
AND `old_pid` IS NOT NULL;
DROP TABLE `%TABLE_PREFIX%T_resp_links`;
-- Transfer notes
INSERT INTO `%TABLE_PREFIX%ticket_thread`
(`ticket_id`, `staff_id`, `thread_type`, `body`, `title`,
`source`, `poster`, `created`, `updated`, `old_pk`)
SELECT `ticket_id`, `staff_id`, 'N', `note`, `title`,
`source`, ( SELECT CONCAT_WS(' ', T2.`firstname`, T2.`lastname`)
FROM `%TABLE_PREFIX%staff` T2
WHERE T2.`staff_id` = `staff_id` ),
`created`, NOW(), `note_id`
FROM `%TABLE_PREFIX%ticket_note`;
-- Transfer email information from messages
INSERT INTO `%TABLE_PREFIX%ticket_email_info`
(`message_id`, `email_mid`, `headers`)
SELECT ( SELECT T2.`id` FROM `%TABLE_PREFIX%ticket_thread` T2
WHERE `msg_id` = T2.`old_pk`
AND `thread_type` = 'M' ),
`messageId`, `headers`
FROM `%TABLE_PREFIX%ticket_message`
WHERE `messageId` IS NOT NULL;
-- Update attachment table
UPDATE `%TABLE_PREFIX%ticket_attachment`
SET `ref_id` = ( SELECT T2.`id` FROM `%TABLE_PREFIX%ticket_thread` T2
WHERE `ref_id` = T2.`old_pk`
AND `ref_type` = T2.`thread_type` );
-- Drop temporary columns
ALTER TABLE `%TABLE_PREFIX%ticket_thread` DROP COLUMN `old_pk`;
ALTER TABLE `%TABLE_PREFIX%ticket_thread` DROP COLUMN `old_pid`;
-- Drop old tables
DROP TABLE `%TABLE_PREFIX%ticket_message`;
DROP TABLE `%TABLE_PREFIX%ticket_response`;
DROP TABLE `%TABLE_PREFIX%ticket_note`;
-- Finished with patch
UPDATE `%TABLE_PREFIX%config`
SET `schema_signature`='abe9c0cb845be52c10fcd7b3e626a589';
......@@ -598,6 +598,14 @@ CREATE TABLE `%TABLE_PREFIX%ticket_lock` (
KEY `staff_id` (`staff_id`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_email_info`;
CREATE TABLE `%TABLE_PREFIX%ticket_email_info` (
`message_id` int(11) unsigned NOT NULL,
`email_mid` varchar(255) NOT NULL,
`headers` text,
KEY `message_id` (`email_mid`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_event`;
CREATE TABLE `%TABLE_PREFIX%ticket_event` (
`ticket_id` int(11) unsigned NOT NULL default '0',
......@@ -612,38 +620,6 @@ CREATE TABLE `%TABLE_PREFIX%ticket_event` (
KEY `ticket_stats` (`timestamp`, `state`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_message`;
CREATE TABLE `%TABLE_PREFIX%ticket_message` (
`msg_id` int(11) unsigned NOT NULL auto_increment,
`ticket_id` int(11) unsigned NOT NULL default '0',
`messageId` varchar(255) default NULL,
`message` text NOT NULL,
`headers` text,
`source` varchar(16) default NULL,
`ip_address` varchar(16) default NULL,
`created` datetime NOT NULL,
`updated` datetime default NULL,
PRIMARY KEY (`msg_id`),
KEY `ticket_id` (`ticket_id`),
KEY `msgId` (`messageId`),
FULLTEXT KEY `message` (`message`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_note`;
CREATE TABLE `%TABLE_PREFIX%ticket_note` (
`note_id` int(11) unsigned NOT NULL auto_increment,
`ticket_id` int(11) unsigned NOT NULL default '0',
`staff_id` int(10) unsigned NOT NULL default '0',
`source` varchar(32) NOT NULL default '',
`title` varchar(255) NOT NULL default 'Generic Intermal Notes',
`note` text NOT NULL,
`created` datetime NOT NULL,
PRIMARY KEY (`note_id`),
KEY `ticket_id` (`ticket_id`),
KEY `staff_id` (`staff_id`),
FULLTEXT KEY `note` (`note`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_priority`;
CREATE TABLE `%TABLE_PREFIX%ticket_priority` (
`priority_id` tinyint(4) NOT NULL auto_increment,
......@@ -664,22 +640,24 @@ INSERT INTO `%TABLE_PREFIX%ticket_priority` (`priority_id`, `priority`, `priorit
(3, 'high', 'High', '#FEE7E7', 2, 1),
(4, 'emergency', 'Emergency', '#FEE7E7', 1, 0);
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_response`;
CREATE TABLE `%TABLE_PREFIX%ticket_response` (
`response_id` int(11) unsigned NOT NULL auto_increment,
`msg_id` int(11) unsigned NOT NULL default '0',
DROP TABLE IF EXISTS `%TABLE_PREFIX%ticket_thread`;
CREATE TABLE `%TABLE_PREFIX%ticket_thread` (
`id` int(11) unsigned NOT NULL auto_increment,
`pid` int(11) unsigned NOT NULL default '0',
`ticket_id` int(11) unsigned NOT NULL default '0',
`staff_id` int(11) unsigned NOT NULL default '0',
`staff_name` varchar(32) NOT NULL default '',
`response` text NOT NULL,
`ip_address` varchar(16) NOT NULL default '',
`thread_type` enum('M','R','N') NOT NULL,
`poster` varchar(128) NOT NULL default '',
`source` varchar(32) NOT NULL default '',
`title` varchar(255),
`body` text NOT NULL,
`ip_address` varchar(64) NOT NULL default '',
`created` datetime NOT NULL,
`updated` datetime NOT NULL,
PRIMARY KEY (`response_id`),
PRIMARY KEY (`id`),
KEY `ticket_id` (`ticket_id`),
KEY `msg_id` (`msg_id`),
KEY `staff_id` (`staff_id`),
FULLTEXT KEY `response` (`response`)
FULLTEXT KEY `body` (`body`)
) ENGINE=MyISAM DEFAULT CHARSET=utf8;
DROP TABLE IF EXISTS `%TABLE_PREFIX%timezone`;
......
f8856d56e51c5cc3416389de78b54515
abe9c0cb845be52c10fcd7b3e626a589
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment