1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301
|
-- --
-- Update an existing OTRS database from 0.5 to 1.0
-- Copyright (C) 2001-2003 Martin Edenhofer <martin+code@otrs.org>
-- --
-- $Id: DBUpdate-to-1.0.mysql.sql,v 1.4 2003/02/09 20:52:17 martin Exp $
-- --
--
-- usage: cat DBUpdate.mysql.sql | mysql -f -u root otrs
--
-- --
-- --
-- 1.0 upgrate
-- --
-- new ticket_lock_index table (for ticket index feature)
CREATE TABLE ticket_lock_index
(
ticket_id BIGINT NOT NULL,
INDEX index_ticket_id (ticket_id)
);
-- standard_attachment
CREATE TABLE standard_attachment
(
id INTEGER NOT NULL AUTO_INCREMENT,
name varchar (150) NOT NULL,
content_type varchar (150) NOT NULL,
content MEDIUMTEXT NOT NULL,
filename varchar (250) NOT NULL,
comment varchar (150),
valid_id smallint NOT NULL,
create_time timestamp(0) NOT NULL,
create_by integer NOT NULL,
change_time timestamp(0) NOT NULL,
change_by integer NOT NULL,
PRIMARY KEY(id),
UNIQUE (name)
);
-- standard_response_attachment
CREATE TABLE standard_response_attachment
(
id INTEGER NOT NULL AUTO_INCREMENT,
standard_attachment_id integer NOT NULL,
standard_response_id integer NOT NULL,
create_time timestamp(0) NOT NULL,
create_by integer NOT NULL,
change_time timestamp(0) NOT NULL,
change_by integer NOT NULL,
PRIMARY KEY(id)
);
-- pop3_account
CREATE TABLE pop3_account
(
id INTEGER NOT NULL AUTO_INCREMENT,
login varchar (200) NOT NULL,
pw varchar (200) NOT NULL,
host varchar (200) NOT NULL,
queue_id integer NOT NULL,
trusted smallint NOT NULL,
comment varchar (250),
valid_id smallint NOT NULL,
create_time timestamp(0) NOT NULL,
create_by integer NOT NULL,
change_time timestamp(0) NOT NULL,
change_by integer NOT NULL,
PRIMARY KEY(id),
UNIQUE (login)
);
-- update states
DELETE FROM ticket_state WHERE name = 'waiting_for_closed+';
DELETE FROM ticket_state WHERE name = 'waiting_for_closed-';
DELETE FROM ticket_state WHERE name = 'waiting_for_customer';
DELETE FROM ticket_state WHERE name = 'waiting_for_info';
DELETE FROM ticket_state WHERE name = 'waiting_for_reminder';
DELETE FROM ticket_history_type WHERE name = 'WatingForClose-';
DELETE FROM ticket_history_type WHERE name = 'WatingForClose+';
DELETE FROM ticket_history_type WHERE name = 'WatingForReminder';
INSERT INTO ticket_history_type
(name, valid_id, create_by, create_time, change_by, change_time)
VALUES
('SetPendingTime', 1, 1, current_timestamp, 1, current_timestamp);
INSERT INTO ticket_history_type
(name, valid_id, create_by, create_time, change_by, change_time)
VALUES
('SetPending', 1, 1, current_timestamp, 1, current_timestamp);
INSERT INTO ticket_state (name, comment, valid_id, create_by, create_time, change_by, change_time)
VALUES ('pending reminder', 'ticket is pending for agent reminder', 1, 1, current_timestamp, 1, current_timestamp);
INSERT INTO ticket_state (name, comment, valid_id, create_by, create_time, change_by, change_time)
VALUES ('pending auto close+', 'ticket is pending for automatic close', 1, 1, current_timestamp, 1, current_timestamp);
INSERT INTO ticket_state (name, comment, valid_id, create_by, create_time, change_by, change_time)
VALUES ('pending auto close-', 'ticket is pending for automatic close', 1, 1, current_timestamp, 1, current_timestamp);
-- update typo
UPDATE ticket_state SET name = 'closed successful', comment = 'ticket is closed succsessful' WHERE name = 'closed succsessful';
UPDATE ticket_state SET name = 'closed unsuccessful', comment = 'ticket is closed unsuccsessful' WHERE name = 'closed unsuccsessful';
UPDATE ticket_history_type SET name = 'Close successful' WHERE name = 'Close succsessful';
UPDATE ticket_history_type SET name = 'Close unsuccessful' WHERE name = 'Close unsuccsessful';
-- table for db loop protection backend module
CREATE TABLE ticket_loop_protection
(
sent_to VARCHAR (250) NOT NULL,
sent_date VARCHAR (150) NOT NULL,
INDEX index_ticket_loop_protection_sent_to (sent_to),
INDEX index_ticket_loop_protection_sent_date (sent_date)
);
-- charset for bulgarian translation
ALTER TABLE charset
MODIFY name VARCHAR (200) NOT NULL,
MODIFY charset VARCHAR (50) NOT NULL,
MODIFY comment VARCHAR (250)
;
INSERT INTO charset
(name, charset, comment, valid_id, create_by, create_time, change_by, change_time)
VALUES
('Cyrillic Charset (Windows-1251)', 'Windows-1251', 'Windows-1251 - cp1251', 1, 1, current_timestamp, 1, current_timestamp);
-- table for attachments in db
CREATE TABLE article_attachment
(
id BIGINT NOT NULL AUTO_INCREMENT,
article_id BIGINT NOT NULL,
filename VARCHAR (250),
content_type VARCHAR (250),
content LONGBLOB,
create_time DATETIME NOT NULL,
create_by INTEGER NOT NULL,
change_time DATETIME NOT NULL,
change_by INTEGER NOT NULL,
PRIMARY KEY(id),
INDEX article_id (article_id)
);
-- table for plain emails in db
CREATE TABLE article_plain
(
id BIGINT NOT NULL AUTO_INCREMENT,
article_id BIGINT NOT NULL,
body MEDIUMTEXT,
create_time DATETIME NOT NULL,
create_by INTEGER NOT NULL,
change_time DATETIME NOT NULL,
change_by INTEGER NOT NULL,
PRIMARY KEY(id),
INDEX article_id (article_id)
);
-- customer preferences
ALTER TABLE customer_preferences MODIFY
user_id VARCHAR (200) NOT NULL
;
ALTER TABLE customer_preferences MODIFY
preferences_key VARCHAR (150) NOT NULL
;
-- --
-- 0.5 BETA 8 upgrate
-- --
-- add ticket_index index
ALTER TABLE ticket_index ADD INDEX index_ticket_id (ticket_id);
-- customer_user
CREATE TABLE customer_user
(
id SMALLINT NOT NULL AUTO_INCREMENT,
login VARCHAR (80) NOT NULL,
email VARCHAR (120) NOT NULL,
customer_id VARCHAR (120) NOT NULL,
pw VARCHAR (20) NOT NULL,
salutation VARCHAR (20),
first_name VARCHAR (40) NOT NULL,
last_name VARCHAR (40) NOT NULL,
valid_id SMALLINT NOT NULL,
comment VARCHAR (120) NOT NULL,
create_time DATETIME NOT NULL,
create_by INTEGER NOT NULL,
change_time DATETIME NOT NULL,
change_by INTEGER NOT NULL,
PRIMARY KEY(id),
UNIQUE (login)
);
-- customer preferences
CREATE TABLE customer_preferences
(
user_id INTEGER NOT NULL,
preferences_key VARCHAR (100) NOT NULL,
preferences_value VARCHAR (250),
INDEX index_customer_preferences_user_id (user_id)
);
-- add ticket_history index
ALTER TABLE ticket_history ADD INDEX ticket_history_create_time (create_time);
-- --
-- BETA 7 upgrate
-- --
-- new ticket_index table (for ticket index feature)
CREATE TABLE ticket_index
(
ticket_id BIGINT NOT NULL,
queue_id INTEGER NOT NULL,
queue VARCHAR (70) NOT NULL,
group_id INTEGER NOT NULL,
s_lock VARCHAR (70) NOT NULL,
s_state VARCHAR (70) NOT NULL,
create_time_unix BIGINT NOT NULL
);
-- new time accounting table
CREATE TABLE time_accounting
(
id BIGINT NOT NULL AUTO_INCREMENT,
ticket_id BIGINT NOT NULL,
article_id BIGINT,
time_unit SMALLINT NOT NULL,
create_time DATETIME NOT NULL,
create_by INTEGER NOT NULL,
change_time DATETIME NOT NULL,
change_by INTEGER NOT NULL,
PRIMARY KEY(id),
INDEX time_accouning_ticket_id(ticket_id)
);
-- new ticket history type
INSERT INTO ticket_history_type
(name, valid_id, create_by, create_time, change_by, change_time)
VALUES
('TimeAccounting', 1, 1, current_timestamp, 1, current_timestamp);
-- new article types
INSERT INTO article_type
(name, valid_id, create_by, create_time, change_by, change_time)
VALUES
('email-notification-ext', 1, 1, current_timestamp, 1, current_timestamp);
INSERT INTO article_type
(name, valid_id, create_by, create_time, change_by, change_time)
VALUES
('email-notification-int', 1, 1, current_timestamp, 1, current_timestamp);
-- new ticket history types
INSERT INTO ticket_history_type
(name, valid_id, create_by, create_time, change_by, change_time)
VALUES
('Forward', 1, 1, current_timestamp, 1, current_timestamp);
INSERT INTO ticket_history_type
(name, valid_id, create_by, create_time, change_by, change_time)
VALUES
('Bounce', 1, 1, current_timestamp, 1, current_timestamp);
-- content_type to display the right charset and it is also used
-- for utf-8 support.
ALTER TABLE article ADD a_content_type VARCHAR (100);
-- --
-- Beta5 bug fixed (thanks to Heiko Baumann)
-- --
ALTER TABLE user_preferences DROP PRIMARY KEY;
ALTER TABLE user_preferences ADD INDEX index_user_preferences_user_id (user_id);
-- --
-- set db to BETA5 state
-- --
-- modify table ticket
ALTER TABLE ticket ADD ticket_answered SMALLINT NOT NULL DEFAULT 0;
-- add ticket_history_type
INSERT INTO ticket_history_type
(name, valid_id, create_by, change_by, change_time)
VALUES
('SendAgentNotification', 1, 1, 1, current_timestamp);
-- add article_type
INSERT INTO article_type
(name, valid_id, create_by, change_by, change_time)
VALUES
('email-external', 1, 1, 1, current_timestamp);
INSERT INTO article_type
(name, valid_id, create_by, change_by, change_time)
VALUES
('email-internal', 1, 1, 1, current_timestamp);
-- create user_preferences
CREATE TABLE user_preferences
(
user_id INTEGER NOT NULL,
preferences_key VARCHAR (100) NOT NULL,
preferences_value VARCHAR (250),
PRIMARY KEY(user_id)
);
-- create session table
CREATE TABLE session
(
id BIGINT NOT NULL AUTO_INCREMENT,
session_id VARCHAR (120) NOT NULL,
value MEDIUMTEXT NOT NULL,
PRIMARY KEY(id),
UNIQUE (session_id),
INDEX index_session_id (session_id)
);
--
-- for BETA1-3
--
-- update message id varchar to 250
ALTER TABLE article MODIFY a_message_id VARCHAR (250);
|