From e51bb66f88166fe1e557c41f96b98842127bbdc8 Mon Sep 17 00:00:00 2001 From: Jared Hancock <jared@osticket.com> Date: Thu, 13 Sep 2012 22:18:47 -0500 Subject: [PATCH] Add chunked file data support This will remove the upper limit of BLOB sizes imposed by MySQL with the max_allowed_packet setting completely. This adds a new table %file_chunk which will contain the filedata in smaller chunks (256kB). It also includes a new class, AttachmentChunkedData, which will handle reading and writing the data, abstracting away the chunks. This is done by migrating data from the %file table to the %file_chunk table. One must beware that this must safely (the migration that is) plug into the both the live osTicket developers as well as the users doing a full upgrade from osTicket-1.6*. For this, the AttachmentFile::save method was patched to use the new AttachmentChunkedData class to write the attachment data to the database in chunks. That is, the migrater will use the new code on the major upgrade and bypass the filedata column of the %file table altogether. Therefore, the patch associated with this commit will not migrate any data for the major upgrade. For developers doing incremental upgrades, the patch included in this commit will transfer the data from the %file data to the new %file_chunk table by chunking it. As written, only the first 16MB of the attachment is migrated. This could easily be adjusted, but it seems like a reasonable limit for now. --- include/class.file.php | 135 ++++++++++-------- .../upgrader/sql/15b30765-dd0022fb.patch.sql | 39 +++++ main.inc.php | 3 +- setup/inc/sql/osTicket-mysql.sql | 15 +- setup/inc/sql/osTicket-mysql.sql.md5 | 2 +- 5 files changed, 130 insertions(+), 64 deletions(-) create mode 100644 include/upgrader/sql/15b30765-dd0022fb.patch.sql diff --git a/include/class.file.php b/include/class.file.php index 36f013a6a..761aba164 100644 --- a/include/class.file.php +++ b/include/class.file.php @@ -91,17 +91,14 @@ class AttachmentFile { return $this->ht['hash']; } + function open() { + return new AttachmentChunkedData($this->id); + } + function sendData() { - $chunk_size = 256 * 1024; - $start = 1; - for (;;) { - list($data) = db_fetch_row(db_query( - 'SELECT SUBSTRING(filedata,'.$start.','.$chunk_size - .') FROM '.FILE_TABLE.' WHERE id='.db_input($this->getId()))); - if (!$data) break; - echo $data; - $start += $chunk_size; - } + $file = $this->open(); + while ($chunk = $file->read()) + echo $chunk; } function getData() { @@ -184,28 +181,9 @@ class AttachmentFile { if (!(db_query($sql) && ($id=db_insert_id()))) return false; - $chunk_size = 256 * 1024; - $start = 0; - # This boils down to a disagreement between the MySQL community and - # developers. I'll refrain from a soapbox discussion here, but MySQL - # will truncate the field to '' when the length of a CONCAT expression - # exceeds the value of max_allowed_packet. See the following bugs for - # more information. The easiest fix is to expand the parameter. - # http://bugs.mysql.com/bug.php?id=22853 - # http://bugs.mysql.com/bug.php?id=34782 - # http://bugs.mysql.com/bug.php?id=63919 - if (db_get_variable('max_allowed_packet') < strlen($file['data'])) - db_set_variable('max_allowed_packet', strlen($file['data']) + $chunk_size); - while ($chunk = substr($file['data'], $start, $chunk_size)) { - $sql='UPDATE '.FILE_TABLE - .' SET filedata = CONCAT(filedata, 0x'.bin2hex($chunk).')' - .' WHERE id='.db_input($id); - if(!db_query($sql)) { - db_query('DELETE FROM '.FILE_TABLE.' WHERE id='.db_input($id).' LIMIT 1'); - return false; - } - $start += $chunk_size; - } + $data = new AttachmentChunkedData($id); + if (!$data->write($file['data'])) + return false; return $id; } @@ -242,44 +220,83 @@ class AttachmentFile { .'SELECT file_id FROM '.FAQ_ATTACHMENT_TABLE .') still_loved' .')'); + AttachmentChunkedData::deleteOrphans(); return db_affected_rows(); } } -class AttachmentList { - function AttachmentList($table, $key) { - $this->table = $table; - $this->key = $key; +/** + * Attachments stored in the database are cut into 256kB chunks and stored + * in the FILE_CHUNK_TABLE to overcome the max_allowed_packet limitation of + * LOB fields in the MySQL database + */ +define('CHUNK_SIZE', 256*1024); # Beware if you change this... +class AttachmentChunkedData { + function AttachmentChunkedData($file) { + $this->_file = $file; + $this->_pos = 0; } - function all() { - if (!isset($this->list)) { - $this->list = array(); - $res=db_query('SELECT file_id FROM '.$this->table - .' WHERE '.$this->key); - while(list($id) = db_fetch_row($res)) { - $this->list[] = new AttachmentFile($id); - } - } - return $this->list; + function length() { + list($length) = db_fetch_row(db_query( + 'SELECT SUM(LENGTH(filedata)) FROM '.FILE_CHUNK_TABLE + .' WHERE file_id='.db_input($this->_file))); + return $length; } - - function getCount() { - return count($this->all()); + + function seek($location) { + $this->_pos=$location; } - function add($fileId) { - db_query( - 'INSERT INTO '.$this->table - .' SET '.$this->key - .' file_id='.db_input($fileId)); + function tell() { + return $this->_pos; } - function remove($fileId) { + function read($length=CHUNK_SIZE) { + # Read requested length of data from attachment chunks + $buffer=''; + while ($length > 0) { + $chunk_id = floor($this->_pos / CHUNK_SIZE); + $start = $this->_pos % CHUNK_SIZE; + $size = min($length, CHUNK_SIZE - $start); + list($block) = @db_fetch_row(db_query( + 'SELECT SUBSTR(filedata, '.($start+1).', '.$size + .') FROM '.FILE_CHUNK_TABLE.' WHERE file_id=' + .db_input($this->_file).' AND chunk_id='.$chunk_id)); + if (!$block) return false; + $buffer .= $block; + $this->_pos += $size; + $length -= $size; + } + return $buffer; + } + + function write($what) { + # Figure out the remaining part of the current chunk (use CHUNK_SIZE + # and $this->_pos, increment pointer into $what and continue to end + # of what + $offset=0; + for (;;) { + $start = $this->_pos % CHUNK_SIZE; + $size = CHUNK_SIZE - $start; + $block = substr($what, $offset, $size); + if (!$block) break; + if (!db_query('REPLACE INTO '.FILE_CHUNK_TABLE + .' SET filedata=INSERT(filedata, '.($start+1).','.$size + .', 0x'.bin2hex($block) + .'), file_id='.db_input($this->_file) + .', chunk_id='.floor($this->_pos / CHUNK_SIZE))) + return false; + $offset += $size; + $this->_pos += strlen($block); + } + return true; + } + + function deleteOrpans() { db_query( - 'DELETE FROM '.$this->table - .' WHERE '.$this->key - .' AND file_id='.db_input($fileId)); + 'DELETE FROM '.FILE_CHUNK_TABLE.' WHERE file_id NOT IN ' + .'( SELECT id FROM '.FILE_TABLE.') still_loved'); + return db_affected_rows(); } } -?> diff --git a/include/upgrader/sql/15b30765-dd0022fb.patch.sql b/include/upgrader/sql/15b30765-dd0022fb.patch.sql new file mode 100644 index 000000000..31307d655 --- /dev/null +++ b/include/upgrader/sql/15b30765-dd0022fb.patch.sql @@ -0,0 +1,39 @@ +/** + * @version v1.7 RC2+ + * @signature dd0022fb14892c0bb6a9700392df2de7 + * + * Migrate file attachment data from %file to %file_chunk + * + */ + +CREATE TABLE `%TABLE_PREFIX%T_file_chunk_id` ( `id` int(11) ); +-- Support up to 16MB attachments +INSERT INTO `%TABLE_PREFIX%T_file_chunk_id` VALUES (0), (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); + +DROP TABLE IF EXISTS `%TABLE_PREFIX%file_chunk`; +CREATE TABLE `%TABLE_PREFIX%file_chunk` ( + `file_id` int(11) NOT NULL, + `chunk_id` int(11) NOT NULL, + `filedata` longblob NOT NULL, + PRIMARY KEY (`file_id`, `chunk_id`) +) ENGINE=MyISAM DEFAULT CHARSET=utf8; + +INSERT INTO `%TABLE_PREFIX%file_chunk` (`file_id`, `chunk_id`, `filedata`) + SELECT T1.`id`, T2.`id`, + SUBSTR(T1.`filedata`, T2.`id` * 256 * 1024 + 1, 256 * 1024) + FROM `%TABLE_PREFIX%file` T1, `%TABLE_PREFIX%T_file_chunk_id` T2 + WHERE T2.`id` * 256 * 1024 < LENGTH(T1.`filedata`); + +ALTER TABLE `%TABLE_PREFIX%file` DROP COLUMN `filedata`; +OPTIMIZE TABLE `%TABLE_PREFIX%file`; + +DROP TABLE `%TABLE_PREFIX%T_file_chunk_id`; + +-- Finished with patch +UPDATE `%TABLE_PREFIX%config` + SET `schema_signature`='dd0022fb14892c0bb6a9700392df2de7'; diff --git a/main.inc.php b/main.inc.php index 8ce394669..235a6341a 100644 --- a/main.inc.php +++ b/main.inc.php @@ -63,7 +63,7 @@ #Current version && schema signature (Changes from version to version) define('THIS_VERSION','1.7-RC2+'); //Shown on admin panel - define('SCHEMA_SIGNATURE','15b3076533123ff617801d89861136c8'); //MD5 signature of the db schema. (used to trigger upgrades) + define('SCHEMA_SIGNATURE','dd0022fb14892c0bb6a9700392df2de7'); //MD5 signature of the db schema. (used to trigger upgrades) #load config info $configfile=''; if(file_exists(ROOT_DIR.'ostconfig.php')) //Old installs prior to v 1.6 RC5 @@ -131,6 +131,7 @@ define('SYSLOG_TABLE',TABLE_PREFIX.'syslog'); define('SESSION_TABLE',TABLE_PREFIX.'session'); define('FILE_TABLE',TABLE_PREFIX.'file'); + define('FILE_CHUNK_TABLE',TABLE_PREFIX.'file_chunk'); define('STAFF_TABLE',TABLE_PREFIX.'staff'); define('DEPT_TABLE',TABLE_PREFIX.'department'); diff --git a/setup/inc/sql/osTicket-mysql.sql b/setup/inc/sql/osTicket-mysql.sql index 6ac95bb52..53e3c5519 100644 --- a/setup/inc/sql/osTicket-mysql.sql +++ b/setup/inc/sql/osTicket-mysql.sql @@ -327,15 +327,24 @@ CREATE TABLE `%TABLE_PREFIX%file` ( `size` varchar(25) NOT NULL default '', `hash` varchar(125) NOT NULL, `name` varchar(255) NOT NULL default '', - `filedata` longblob NOT NULL, `created` datetime NOT NULL, PRIMARY KEY (`id`), KEY `hash` (`hash`) ) ENGINE=MyISAM DEFAULT CHARSET=utf8; -INSERT INTO `%TABLE_PREFIX%file` (`id`, `type`, `size`, `hash`, `name`, `filedata`, `created`) VALUES -(1, 'text/plain', '25', '670c6cc1d1dfc97fad20e5470251b255', 'osTicket.txt', 0x43616e6e6564206174746163686d656e747320726f636b210a, NOW()); +INSERT INTO `%TABLE_PREFIX%file` (`id`, `type`, `size`, `hash`, `name`, `created`) VALUES +(1, 'text/plain', '25', '670c6cc1d1dfc97fad20e5470251b255', 'osTicket.txt', NOW()); +DROP TABLE IF EXISTS `%TABLE_PREFIX%file_chunk`; +CREATE TABLE `%TABLE_PREFIX%file_chunk` ( + `file_id` int(11) NOT NULL, + `chunk_id` int(11) NOT NULL, + `filedata` longblob NOT NULL, + PRIMARY KEY (`file_id`, `chunk_id`) +) ENGINE=MyISAM DEFAULT CHARSET=utf8; + +INSERT INTO `%TABLE_PREFIX%file_chunk` (`file_id`, `chunk_id`, `filedata`) +VALUES (1, 0, 0x43616e6e6564206174746163686d656e747320726f636b210a); DROP TABLE IF EXISTS `%TABLE_PREFIX%groups`; CREATE TABLE `%TABLE_PREFIX%groups` ( diff --git a/setup/inc/sql/osTicket-mysql.sql.md5 b/setup/inc/sql/osTicket-mysql.sql.md5 index 11c872a50..e96b33654 100644 --- a/setup/inc/sql/osTicket-mysql.sql.md5 +++ b/setup/inc/sql/osTicket-mysql.sql.md5 @@ -1 +1 @@ -15b3076533123ff617801d89861136c8 +dd0022fb14892c0bb6a9700392df2de7 -- GitLab