Skip to content

Commit

Permalink
[jan] Fix migrating NULL values to BLOB on Oracle.
Browse files Browse the repository at this point in the history
  • Loading branch information
yunosh committed Oct 22, 2014
1 parent d5dec92 commit 2694237
Show file tree
Hide file tree
Showing 3 changed files with 39 additions and 20 deletions.
45 changes: 30 additions & 15 deletions framework/Db/lib/Horde/Db/Adapter/Oracle/Schema.php
Expand Up @@ -496,27 +496,42 @@ public function changeColumn($tableName, $columnName, $type, $options = array())
if ($type == 'binary' && $column->getType() != 'binary') {
$this->beginDbTransaction();
$this->addColumn($tableName, $columnName . '_tmp', $type, $options);
$this->execute('
CREATE OR REPLACE FUNCTION CLOB_TO_BLOB (p_clob CLOB) RETURN BLOB
AS
l_blob BLOB;
l_dest_offset INTEGER := 1;
l_source_offset INTEGER := 1;
l_lang_context INTEGER := DBMS_LOB.DEFAULT_LANG_CTX;
l_warning INTEGER := DBMS_LOB.WARN_INCONVERTIBLE_CHAR;
BEGIN
DBMS_LOB.CREATETEMPORARY(l_blob, TRUE);
DBMS_LOB.CONVERTTOBLOB
(
dest_lob => l_blob,
src_clob => p_clob,
amount => DBMS_LOB.LOBMAXSIZE,
dest_offset => l_dest_offset,
src_offset => l_source_offset,
blob_csid => DBMS_LOB.DEFAULT_CSID,
lang_context => l_lang_context,
warning => l_warning
);
RETURN l_blob;
END;
');
$this->update(sprintf(
'UPDATE %s SET %s = UTL_RAW.CAST_TO_RAW(%s) WHERE LENGTH(%3$s) <= 2000',
'UPDATE %s SET %s = CLOB_TO_BLOB(%s) WHERE %s IS NOT NULL',
$this->quoteTableName($tableName),
$this->quoteColumnName($columnName . '_tmp'),
$this->quoteColumnName($columnName),
$this->quoteColumnName($columnName)
));
$this->execute(sprintf(
'DECLARE CURSOR cur IS SELECT %s, %s FROM %s WHERE LENGTH(%s) > 2000 FOR UPDATE; new blob; old %s; BEGIN OPEN cur; IF cur%%ISOPEN THEN LOOP FETCH cur INTO old, new; EXIT WHEN cur%%NOTFOUND; DBMS_LOB.WRITE(new, LENGTH(old), 1, UTL_RAW.CAST_TO_RAW(SUBSTR(old, 1, LENGTH(old)))); END LOOP; CLOSE cur; END IF; END;',
$this->quoteColumnName($columnName),
$this->quoteColumnName($columnName . '_tmp'),
$this->update(sprintf(
'UPDATE %s SET %s = NULL WHERE %s IS NULL',
$this->quoteTableName($tableName),
$this->quoteColumnName($columnName),
$this->typeToSql(
$column->getType(),
$column->getType() == 'integer' || $column->getType() == 'text'
? null
: $column->getLimit(),
$column->precision(),
$column->scale(),
$column->isUnsigned()
)
$this->quoteColumnName($columnName . '_tmp'),
$this->quoteColumnName($columnName)
));
$this->removeColumn($tableName, $columnName);
$this->renameColumn($tableName, $columnName . '_tmp', $columnName);
Expand Down
4 changes: 2 additions & 2 deletions framework/Db/package.xml
Expand Up @@ -34,7 +34,7 @@
</stability>
<license uri="http://www.horde.org/licenses/bsd">BSD-2-Clause</license>
<notes>
*
* [jan] Fix migrating NULL values to BLOB on Oracle.
</notes>
<contents>
<dir baseinstalldir="/" name="/">
Expand Down Expand Up @@ -826,7 +826,7 @@
<date>2014-10-02</date>
<license uri="http://www.horde.org/licenses/bsd">BSD-2-Clause</license>
<notes>
*
* [jan] Fix migrating NULL values to BLOB on Oracle.
</notes>
</release>
</changelog>
Expand Down
10 changes: 7 additions & 3 deletions framework/Db/test/Horde/Db/Adapter/Oci8Test.php
Expand Up @@ -21,6 +21,7 @@ class Horde_Db_Adapter_Oci8Test extends Horde_Db_Adapter_TestBase
{
public static function setUpBeforeClass()
{
self::$_reason = 'The OCI8 adapter is not available';
if (extension_loaded('oci8')) {
self::$_skip = false;
list($conn,) = static::_getConnection();
Expand Down Expand Up @@ -167,14 +168,17 @@ public function testChangeColumnType()
$table->end();
$this->_conn->insert('INSERT INTO text_to_binary (data) VALUES (?)',
array('foo'));
$this->_conn->insert('INSERT INTO text_to_binary (data) VALUES (?)',
array(null));

$this->_conn->changeColumn('text_to_binary', 'data', 'binary');

$afterChange = $this->_getColumn('text_to_binary', 'data');
$this->assertEquals('blob', $afterChange->getSqlType());
$value = $this->_conn->selectValue('SELECT data FROM text_to_binary');
$this->assertInstanceOf('OCI-Lob', $value);
$this->assertEquals('foo', $value->read($value->size()));
$values = $this->_conn->selectValues('SELECT data FROM text_to_binary');
$this->assertInstanceOf('OCI-Lob', $values[0]);
$this->assertEquals('foo', $values[0]->read($values[0]->size()));
$this->assertEquals(null, $values[1]);
}

public function testChangeColumnLimit()
Expand Down

0 comments on commit 2694237

Please sign in to comment.