From: Chuck Hagenbuch Date: Mon, 5 Jul 2010 19:59:04 +0000 (-0400) Subject: Add a Horde_Db_Adapter for the traditional PHP mysql extension. X-Git-Url: https://git.internetallee.de/?a=commitdiff_plain;h=4f49158270abf6868eba0ba52c52fda9e3f04aaa;p=horde.git Add a Horde_Db_Adapter for the traditional PHP mysql extension. --- diff --git a/framework/Db/lib/Horde/Db/Adapter/Mysql.php b/framework/Db/lib/Horde/Db/Adapter/Mysql.php new file mode 100644 index 000000000..9930460aa --- /dev/null +++ b/framework/Db/lib/Horde/Db/Adapter/Mysql.php @@ -0,0 +1,405 @@ + + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @category Horde + * @package Horde_Db + * @subpackage Adapter + */ + +/** + * MySQL Improved Horde_Db_Adapter + * + * @author Mike Naberezny + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @category Horde + * @package Horde_Db + * @subpackage Adapter + */ +class Horde_Db_Adapter_Mysql extends Horde_Db_Adapter_Base +{ + /** + * Mysql database connection handle. + * @var resource + */ + protected $_connection = null; + + /** + * Last auto-generated insert_id + * @var integer + */ + protected $_insertId; + + /** + * @var string + */ + protected $_schemaClass = 'Horde_Db_Adapter_Mysql_Schema'; + + + /*########################################################################## + # Public + ##########################################################################*/ + + /** + * Returns the human-readable name of the adapter. Use mixed case - one + * can always use downcase if needed. + * + * @return string + */ + public function adapterName() + { + return 'MySQL'; + } + + /** + * Does this adapter support migrations? Backend specific, as the + * abstract adapter always returns +false+. + * + * @return boolean + */ + public function supportsMigrations() + { + return true; + } + + + /*########################################################################## + # Connection Management + ##########################################################################*/ + + /** + * Connect to the db + */ + public function connect() + { + if ($this->_active) { + return; + } + + $config = $this->_parseConfig(); + + $oldErrorReporting = error_reporting(0); + $oldTrackErrors = ini_set('track_errors', 1); + $mysql = mysql_connect( + $config['host'], $config['username'], $config['password']); + error_reporting($oldErrorReporting); + ini_set('track_errors', $oldTrackErrors); + + if (!$mysql) { + throw new Horde_Db_Exception('Connect failed: ' . $php_errormsg); + } + if (!mysql_select_db($config['dbname'])) { + throw new Horde_Db_Exception('Could not select database: ' . $config['dbname']); + } + + $this->_connection = $mysql; + $this->_active = true; + + // Set the default charset. http://dev.mysql.com/doc/refman/5.1/en/charset-connection.html + if (!empty($config['charset'])) { + $this->setCharset($config['charset']); + } + } + + /** + * Disconnect from db + */ + public function disconnect() + { + if ($this->_connection) { mysql_close($this->_connection); } + $this->_connection = null; + $this->_active = false; + } + + /** + * Check if the connection is active + * + * @return boolean + */ + public function isActive() + { + return isset($this->_connection) && mysql_ping($this->_connection); + } + + + /*########################################################################## + # Quoting + ##########################################################################*/ + + /** + * Quotes a string, escaping any ' (single quote) and \ (backslash) + * characters.. + * + * @param string $string + * @return string + */ + public function quoteString($string) + { + return "'" . mysql_real_escape_string($string, $this->_connection) . "'"; + } + + + /*########################################################################## + # Database Statements + ##########################################################################*/ + + /** + * Returns an array of records with the column names as keys, and + * column values as values. + * + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + * @return array + */ + public function select($sql, $arg1 = null, $arg2 = null) + { + return new Horde_Db_Adapter_Mysql_Result($this, $sql, $arg1, $arg2); + } + + /** + * Returns an array of record hashes with the column names as keys and + * column values as values. + * + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + */ + public function selectAll($sql, $arg1 = null, $arg2 = null) + { + $result = $this->execute($sql, $arg1, $arg2); + $rows = array(); + if ($result) { + while ($row = mysql_fetch_array($result)) { + $rows[] = $row; + } + } + return $rows; + } + + /** + * Returns a record hash with the column names as keys and column values + * as values. + * + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + * @return array + */ + public function selectOne($sql, $arg1=null, $arg2=null) + { + $result = $this->execute($sql, $arg1, $arg2); + return $result ? mysql_fetch_array($result) : array(); + } + + /** + * Returns a single value from a record + * + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + * @return string + */ + public function selectValue($sql, $arg1=null, $arg2=null) + { + $result = $this->selectOne($sql, $arg1, $arg2); + return $result ? current($result) : null; + } + + /** + * Returns an array of the values of the first column in a select: + * select_values("SELECT id FROM companies LIMIT 3") => [1,2,3] + * + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + */ + public function selectValues($sql, $arg1=null, $arg2=null) + { + $values = array(); + $result = $this->execute($sql, $arg1, $arg2); + if ($result) { + while ($row = mysql_fetch_row($result)) { + $values[] = $row[0]; + } + } + return $values; + } + + /** + * Executes the SQL statement in the context of this connection. + * + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + */ + public function execute($sql, $arg1=null, $arg2=null) + { + if (is_array($arg1)) { + $sql = $this->_replaceParameters($sql, $arg1); + $name = $arg2; + } else { + $name = $arg1; + } + + $t = new Horde_Support_Timer(); + $t->push(); + + $stmt = mysql_query($sql, $this->_connection); + if (!$stmt) { + $this->_logInfo($sql, 'QUERY FAILED: ' . mysql_error($this->_connection)); + $this->_logInfo($sql, $name); + throw new Horde_Db_Exception('QUERY FAILED: ' . mysql_error($this->_connection) . "\n\n" . $sql, + $this->_errorCode(null, mysql_errno($this->_connection))); + } + + $this->_logInfo($sql, $name, $t->pop()); + + $this->_rowCount = mysql_affected_rows($this->_connection); + $this->_insertId = mysql_insert_id($this->_connection); + return $stmt; + } + + /** + * Returns the last auto-generated ID from the affected table. + * + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + * @param string $pk + * @param int $idValue + * @param string $sequenceName + */ + public function insert($sql, $arg1 = null, $arg2 = null, $pk = null, $idValue = null, $sequenceName = null) + { + $this->execute($sql, $arg1, $arg2); + return isset($idValue) ? $idValue : $this->_insertId; + } + + /** + * Begins the transaction (and turns off auto-committing). + */ + public function beginDbTransaction() + { + $this->_transactionStarted = true; + @mysql_query('SET AUTOCOMMIT=0', $this->_connection) && @mysql_query('BEGIN', $this->_connection); + } + + /** + * Commits the transaction (and turns on auto-committing). + */ + public function commitDbTransaction() + { + @mysql_query('COMMIT', $this->_connection) && @mysql_query('SET AUTOCOMMIT=1', $this->_connection); + $this->_transactionStarted = false; + } + + /** + * Rolls back the transaction (and turns on auto-committing). Must be + * done if the transaction block raises an exception or returns false. + */ + public function rollbackDbTransaction() + { + if (! $this->_transactionStarted) { return; } + + @mysql_query('ROLLBACK', $this->_connection) && @mysql_query('SET AUTOCOMMIT=1', $this->_connection); + $this->_transactionStarted = false; + } + + /** + * Appends +LIMIT+ and +OFFSET+ options to a SQL statement. + * + * @param string $sql + * @param array $options + * @return string + */ + public function addLimitOffset($sql, $options) + { + if (isset($options['limit']) && $limit = $options['limit']) { + if (isset($options['offset']) && $offset = $options['offset']) { + $sql .= " LIMIT $offset, $limit"; + } else { + $sql .= " LIMIT $limit"; + } + } + return $sql; + } + + + /*########################################################################## + # Protected + ##########################################################################*/ + + /** + * Return a standard error code + * + * @param string $sqlstate + * @param integer $errno + * @return integer + */ + protected function _errorCode($sqlstate, $errno) + { + /*@TODO do something with standard sqlstate vs. MySQL error codes vs. whatever else*/ + return $errno; + } + + /** + * Parse configuration array into options for mysql_connect + * + * @throws Horde_Db_Exception + * @return array [host, username, password, dbname] + */ + protected function _parseConfig() + { + // check required config keys are present + $required = array('username'); + $diff = array_diff_key(array_flip($required), $this->_config); + if (! empty($diff)) { + $msg = 'Required config missing: ' . implode(', ', array_keys($diff)); + throw new Horde_Db_Exception($msg); + } + + $rails2mysqli = array('database' => 'dbname'); + foreach ($rails2mysqli as $from => $to) { + if (isset($this->_config[$from])) { + $this->_config[$to] = $this->_config[$from]; + unset($this->_config[$from]); + } + } + + if (isset($this->_config['port'])) { + if (empty($this->_config['host'])) { + $msg = 'host is required if port is specified'; + throw new Horde_Db_Exception($msg); + } + $this->_config['host'] .= ':' . $this->_config['port']; + unset($this->_config['port']); + } + + if (!empty($this->_config['socket'])) { + if (!empty($this->_config['host']) && $this->_config['host'] != 'localhost') { + $msg = 'can only specify host or socket, not both'; + throw new Horde_Db_Exception($msg); + } + $this->_config['host'] = ':' . $this->_config['socket']; + unset($this->_config['socket']); + } + + $config = $this->_config; + + if (!isset($config['host'])) $config['host'] = null; + if (!isset($config['username'])) $config['username'] = null; + if (!isset($config['password'])) $config['password'] = null; + if (!isset($config['dbname'])) $config['dbname'] = null; + + return $config; + } + +} diff --git a/framework/Db/lib/Horde/Db/Adapter/Mysql/Result.php b/framework/Db/lib/Horde/Db/Adapter/Mysql/Result.php new file mode 100644 index 000000000..e12510e14 --- /dev/null +++ b/framework/Db/lib/Horde/Db/Adapter/Mysql/Result.php @@ -0,0 +1,196 @@ + + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @category Horde + * @package Horde_Db + * @subpackage Adapter + */ + +/** + * @author Mike Naberezny + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @category Horde + * @package Horde_Db + * @subpackage Adapter + */ +class Horde_Db_Adapter_Mysql_Result implements Iterator +{ + /** + * @var Horde_Db_Adapter + */ + protected $_adapter; + + /** + * @var string + */ + protected $_sql; + + /** + * @var mixed + */ + protected $_arg1; + + /** + * @var string + */ + protected $_arg2; + + /** + * Result resource + * @var resource + */ + protected $_result; + + /** + * Current row + * @var array + */ + protected $_current; + + /** + * Current offset + * @var integer + */ + protected $_index; + + /** + * Are we at the end of the result? + * @var boolean + */ + protected $_eof; + + /** + * Constructor + * + * @param Horde_Db_Adapter $adapter + * @param string $sql + * @param mixed $arg1 Either an array of bound parameters or a query name. + * @param string $arg2 If $arg1 contains bound parameters, the query name. + */ + public function __construct($adapter, $sql, $arg1 = null, $arg2 = null) + { + $this->_adapter = $adapter; + $this->_sql = $sql; + $this->_arg1 = $arg1; + $this->_arg2 = $arg2; + } + + /** + * Destructor - release any resources. + */ + public function __destruct() + { + if ($this->_result) { + unset($this->_result); + } + } + + /** + * Implementation of the rewind() method for iterator. + */ + public function rewind() + { + if ($this->_result) { + unset($this->_result); + } + $this->_current = null; + $this->_index = null; + $this->_eof = true; + $this->_result = $this->_adapter->execute($this->_sql, $this->_arg1, $this->_arg2); + + $this->next(); + } + + /** + * Implementation of the current() method for iterator. + * + * @return mixed The current row, or null if no rows. + */ + public function current() + { + if (is_null($this->_result)) { + $this->rewind(); + } + return $this->_current; + } + + /** + * Implementation of the key() method for iterator. + * + * @return mixed The current row number (starts at 0), or NULL if no rows + */ + public function key() + { + if (is_null($this->_result)) { + $this->rewind(); + } + return $this->_index; + } + + /** + * Implementation of the next() method. + * + * @return array|null The next row in the resultset or null if there are no + * more results. + */ + public function next() + { + if (is_null($this->_result)) { + $this->rewind(); + } + + if ($this->_result) { + $row = mysql_fetch_array($this->_result, MYSQL_BOTH); + if (!$row) { + $this->_eof = true; + } else { + $this->_eof = false; + + if (is_null($this->_index)) { + $this->_index = 0; + } else { + ++$this->_index; + } + + $this->_current = $row; + } + } + + return $this->_current; + } + + /** + * Return the current row and advance the recordset one row. + */ + public function fetch() + { + if (!$this->valid()) { + return null; + } + $row = $this->current(); + $this->next(); + return $row; + } + + /** + * Implementation of the valid() method for iterator + * + * @return boolean Whether the iteration is valid + */ + public function valid() + { + if (is_null($this->_result)) { + $this->rewind(); + } + return !$this->_eof; + } + +} diff --git a/framework/Db/lib/Horde/Db/Adapter/Mysqli.php b/framework/Db/lib/Horde/Db/Adapter/Mysqli.php index cba44d165..6b5b52b9d 100644 --- a/framework/Db/lib/Horde/Db/Adapter/Mysqli.php +++ b/framework/Db/lib/Horde/Db/Adapter/Mysqli.php @@ -163,8 +163,7 @@ class Horde_Db_Adapter_Mysqli extends Horde_Db_Adapter_Base */ public function disconnect() { - if ($this->_connection) - $this->_connection->close(); + if ($this->_connection) { $this->_connection->close(); } $this->_connection = null; $this->_active = false; } @@ -304,7 +303,7 @@ class Horde_Db_Adapter_Mysqli extends Horde_Db_Adapter_Base $name = $arg1; } - $t = new Horde_Support_Timer; + $t = new Horde_Support_Timer(); $t->push(); $stmt = $this->_connection->query($sql); diff --git a/framework/Db/package.xml b/framework/Db/package.xml index 7a12a3d9e..eea178470 100644 --- a/framework/Db/package.xml +++ b/framework/Db/package.xml @@ -52,6 +52,7 @@ http://pear.php.net/dtd/package-2.0.xsd"> + @@ -77,6 +78,7 @@ http://pear.php.net/dtd/package-2.0.xsd"> + @@ -129,7 +131,9 @@ http://pear.php.net/dtd/package-2.0.xsd"> + + diff --git a/framework/Db/test/Horde/Db/Adapter/MysqlSuite.php b/framework/Db/test/Horde/Db/Adapter/MysqlSuite.php new file mode 100644 index 000000000..4792e5afe --- /dev/null +++ b/framework/Db/test/Horde/Db/Adapter/MysqlSuite.php @@ -0,0 +1,91 @@ + + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @category Horde + * @package Horde_Db + * @subpackage UnitTests + */ + +/** + * @author Mike Naberezny + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @group horde_db + * @category Horde + * @package Horde_Db + * @subpackage UnitTests + */ +class Horde_Db_Adapter_MysqlSuite extends PHPUnit_Framework_TestSuite +{ + public static function suite() + { + $suite = new self('Horde Framework - Horde_Db - MySQL Adapter'); + + $skip = true; + if (extension_loaded('mysql')) { + try { + list($conn,) = $suite->getConnection(); + $skip = false; + $conn->disconnect(); + } catch (Exception $e) {var_dump($e); exit;} + } + + if ($skip) { + $skipTest = new Horde_Db_Adapter_MissingTest('testMissingAdapter'); + $skipTest->adapter = 'MySQL'; + $suite->addTest($skipTest); + return $suite; + } + + require_once dirname(__FILE__) . '/MysqlTest.php'; + require_once dirname(__FILE__) . '/Mysql/ColumnTest.php'; + require_once dirname(__FILE__) . '/Mysql/ColumnDefinitionTest.php'; + require_once dirname(__FILE__) . '/Mysql/TableDefinitionTest.php'; + + $suite->addTestSuite('Horde_Db_Adapter_MysqlTest'); + $suite->addTestSuite('Horde_Db_Adapter_Mysql_ColumnTest'); + $suite->addTestSuite('Horde_Db_Adapter_Mysql_ColumnDefinitionTest'); + $suite->addTestSuite('Horde_Db_Adapter_Mysql_TableDefinitionTest'); + + return $suite; + } + + public function getConnection() + { + $config = getenv('DB_ADAPTER_MYSQL_TEST_CONFIG'); + if ($config && !is_file($config)) { + $config = array_merge(array('host' => 'localhost', 'username' => '', 'password' => '', 'dbname' => 'test'), json_decode($config, true)); + } else { + if (!$config) { + $config = dirname(__FILE__) . '/../conf.php'; + } + if (file_exists($config)) { + require $config; + } + if (!isset($conf['db']['adapter']['mysql']['test'])) { + throw new Exception('No configuration for mysql test'); + } + $config = $conf['db']['adapter']['mysql']['test']; + } + + $conn = new Horde_Db_Adapter_Mysql($config); + + $cache = new Horde_Cache_Mock(); + $conn->setCache($cache); + + return array($conn, $cache); + } + + protected function setUp() + { + $this->sharedFixture = $this; + } + +} diff --git a/framework/Db/test/Horde/Db/Adapter/MysqlTest.php b/framework/Db/test/Horde/Db/Adapter/MysqlTest.php new file mode 100644 index 000000000..e33713294 --- /dev/null +++ b/framework/Db/test/Horde/Db/Adapter/MysqlTest.php @@ -0,0 +1,1330 @@ + + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @category Horde + * @package Horde_Db + * @subpackage UnitTests + */ + +/** + * @author Mike Naberezny + * @author Derek DeVries + * @author Chuck Hagenbuch + * @license http://opensource.org/licenses/bsd-license.php + * @group horde_db + * @category Horde + * @package Horde_Db + * @subpackage UnitTests + */ +class Horde_Db_Adapter_MysqlTest extends PHPUnit_Framework_TestCase +{ + // @todo - add logger instance + protected function setUp() + { + list($this->_conn, $this->_cache) = $this->sharedFixture->getConnection(); + + // clear out detritus from any previous test runs. + $this->_dropTestTables(); + + $table = $this->_conn->createTable('unit_tests'); + $table->column('integer_value', 'integer', array('limit' => 11, 'default' => 0)); + $table->column('string_value', 'string', array('limit' => 255, 'default' => '')); + $table->column('text_value', 'text', array('null' => false, 'default' => '')); + $table->column('float_value', 'float', array('precision' => 2, 'scale' => 1, 'default' => 0.0)); + $table->column('decimal_value', 'decimal', array('precision' => 2, 'scale' => 1, 'default' => 0.0)); + $table->column('datetime_value', 'datetime', array('default' => '0000-00-00 00:00:00')); + $table->column('date_value', 'date', array('default' => '0000-00-00')); + $table->column('time_value', 'time', array('default' => '00:00:00')); + $table->column('blob_value', 'binary', array('null' => false, 'default' => '')); + $table->column('boolean_value', 'boolean', array('default' => false)); + $table->column('email_value', 'string', array('limit' => 255, 'default' => '')); + $table->end(); + $this->_conn->addIndex('unit_tests', 'string_value', array('name' => 'string_value')); + $this->_conn->addIndex('unit_tests', 'integer_value', array('name' => 'integer_value', 'unique' => true)); + $this->_conn->addIndex('unit_tests', array('integer_value', 'string_value'), array('name' => 'integer_string')); + + // read sql file for statements + $statements = array(); + $current_stmt = ''; + $fp = fopen(dirname(__FILE__) . '/../fixtures/unit_tests.sql', 'r'); + while ($line = fgets($fp, 8192)) { + $line = rtrim(preg_replace('/^(.*)--.*$/s', '\1', $line)); + if (!$line) { + continue; + } + + $current_stmt .= $line; + + if (substr($line, -1) == ';') { + // leave off the ending ; + $statements[] = substr($current_stmt, 0, -1); + $current_stmt = ''; + } + } + + // run statements + foreach ($statements as $stmt) { + $this->_conn->execute($stmt); + } + } + + protected function tearDown() + { + // clean up + $this->_dropTestTables(); + + // close connection + $this->_conn->disconnect(); + } + + + /*########################################################################## + # Connection + ##########################################################################*/ + + public function testConnect() + { + $this->assertTrue($this->_conn->isActive()); + } + + public function testDisconnect() + { + $this->_conn->disconnect(); + $this->assertFalse($this->_conn->isActive()); + + $this->_conn->connect(); + $this->assertTrue($this->_conn->isActive()); + } + + public function testReconnect() + { + $this->_conn->reconnect(); + $this->assertTrue($this->_conn->isActive()); + } + + + /*########################################################################## + # Accessor + ##########################################################################*/ + + public function testAdapterName() + { + $this->assertEquals('MySQL', $this->_conn->adapterName()); + } + + public function testSupportsMigrations() + { + $this->assertTrue($this->_conn->supportsMigrations()); + } + + public function testSupportsCountDistinct() + { + $this->assertTrue($this->_conn->supportsCountDistinct()); + } + + public function testGetCharset() + { + $this->assertEquals('utf8', strtolower($this->_conn->getCharset())); + } + + + /*########################################################################## + # Database Statements + ##########################################################################*/ + + public function testExecute() + { + $sql = "SELECT * FROM unit_tests WHERE id='1'"; + $result = $this->_conn->execute($sql); + $row = mysql_fetch_assoc($result); + $this->assertEquals(1, $row['id']); + } + + public function testSelect() + { + $sql = "SELECT * FROM unit_tests WHERE id='1'"; + $result = $this->_conn->select($sql); + $this->assertType('Traversable', $result); + $this->assertGreaterThan(0, count($result)); + + foreach ($result as $row) break; + $this->assertType('array', $row); + $this->assertEquals(1, $row['id']); + } + + public function testSelectWithBoundParameters() + { + $sql = "SELECT * FROM unit_tests WHERE id=?"; + $result = $this->_conn->select($sql, array(1)); + $this->assertType('Traversable', $result); + $this->assertGreaterThan(0, count($result)); + + foreach ($result as $row) break; + $this->assertType('array', $row); + $this->assertEquals(1, $row['id']); + } + + public function testSelectWithBoundParametersQuotesString() + { + $sql = "SELECT * FROM unit_tests WHERE string_value=?"; + $result = $this->_conn->select($sql, array('name a')); + $this->assertType('Traversable', $result); + $this->assertGreaterThan(0, count($result)); + + foreach ($result as $row) break; + $this->assertType('array', $row); + $this->assertEquals(1, $row['id']); + } + + public function testSelectAll() + { + $sql = "SELECT * FROM unit_tests WHERE id='1'"; + $result = $this->_conn->selectAll($sql); + $this->assertType('array', $result); + $this->assertGreaterThan(0, count($result)); + $this->assertEquals(1, $result[0]['id']); + } + + public function testSelectOne() + { + $sql = "SELECT * FROM unit_tests WHERE id='1'"; + $result = $this->_conn->selectOne($sql); + $this->assertEquals(1, $result['id']); + } + + public function testSelectValue() + { + $sql = "SELECT * FROM unit_tests WHERE id='1'"; + $result = $this->_conn->selectValue($sql); + $this->assertEquals(1, $result); + } + + public function testSelectValues() + { + $sql = "SELECT * FROM unit_tests"; + $result = $this->_conn->selectValues($sql); + $this->assertEquals(array(1, 2, 3, 4, 5, 6), $result); + } + + public function testInsert() + { + $sql = "INSERT INTO unit_tests (id, integer_value) VALUES (7, 999)"; + $result = $this->_conn->insert($sql); + + $this->assertEquals(7, $result); + } + + public function testUpdate() + { + $sql = "UPDATE unit_tests SET integer_value=999 WHERE id IN (1)"; + $result = $this->_conn->update($sql); + + $this->assertEquals(1, $result); + } + + public function testDelete() + { + $sql = "DELETE FROM unit_tests WHERE id IN (1,2)"; + $result = $this->_conn->delete($sql); + + $this->assertEquals(2, $result); + } + + public function testTransactionStarted() + { + $this->assertFalse($this->_conn->transactionStarted()); + $this->_conn->beginDbTransaction(); + + $this->assertTrue($this->_conn->transactionStarted()); + $this->_conn->commitDbTransaction(); + + $this->assertFalse($this->_conn->transactionStarted()); + } + + public function testTransactionCommit() + { + $this->_conn->beginDbTransaction(); + $sql = "INSERT INTO unit_tests (id, integer_value) VALUES (7, 999)"; + $this->_conn->insert($sql); + $this->_conn->commitDbTransaction(); + + // make sure it inserted + $sql = "SELECT integer_value FROM unit_tests WHERE id='7'"; + $this->assertEquals('999', $this->_conn->selectValue($sql)); + } + + public function testTransactionRollback() + { + $this->_conn->beginDbTransaction(); + $sql = "INSERT INTO unit_tests (id, integer_value) VALUES (7, 999)"; + $this->_conn->insert($sql); + $this->_conn->rollbackDbTransaction(); + + // make sure it inserted + $sql = "SELECT integer_value FROM unit_tests WHERE id='7'"; + $this->assertEquals(null, $this->_conn->selectValue($sql)); + } + + + /*########################################################################## + # Quoting + ##########################################################################*/ + + public function testQuoteNull() + { + $this->assertEquals('NULL', $this->_conn->quote(null)); + } + + public function testQuoteTrue() + { + $this->assertEquals('1', $this->_conn->quote(true)); + } + + public function testQuoteFalse() + { + $this->assertEquals('0', $this->_conn->quote(false)); + } + + public function testQuoteString() + { + $this->assertEquals("'my string'", $this->_conn->quote('my string')); + } + + public function testQuoteDirtyString() + { + $this->assertEquals("'derek\'s string'", $this->_conn->quote('derek\'s string')); + } + + public function testQuoteColumnName() + { + $col = new Horde_Db_Adapter_Mysql_Column('age', 'NULL', 'int(11)'); + $this->assertEquals('1', $this->_conn->quote(true, $col)); + } + + + /*########################################################################## + # Schema Statements + ##########################################################################*/ + + /** + * We specifically do a manual INSERT here, and then test only the SELECT + * functionality. This allows us to more easily catch INSERT being broken, + * but SELECT actually working fine. + */ + public function testNativeDecimalInsertManualVsAutomatic() + { + $this->_createTestUsersTable(); + + $correctValue = 12345678901234567890.0123456789; + + $this->_conn->addColumn("users", "wealth", 'decimal', array('precision' => 30, 'scale' => 10)); + + // do a manual insertion + $this->_conn->execute("INSERT INTO users (wealth) VALUES ('12345678901234567890.0123456789')"); + + // SELECT @todo - type cast attribute values + $user = (object)$this->_conn->selectOne('SELECT * FROM users'); + // assert_kind_of BigDecimal, row.wealth + + // If this assert fails, that means the SELECT is broken! + $this->assertEquals($correctValue, $user->wealth); + + // Reset to old state + $this->_conn->delete('DELETE FROM users'); + + // Now use the Adapter insertion + $this->_conn->insert('INSERT INTO users (wealth) VALUES (12345678901234567890.0123456789)'); + + // SELECT @todo - type cast attribute values + $user = (object)$this->_conn->selectOne('SELECT * FROM users'); + // assert_kind_of BigDecimal, row.wealth + + // If these asserts fail, that means the INSERT (create function, or cast to SQL) is broken! + $this->assertEquals($correctValue, $user->wealth); + } + + public function testNativeTypes() + { + $this->_createTestUsersTable(); + + $this->_conn->addColumn("users", "last_name", 'string'); + $this->_conn->addColumn("users", "bio", 'text'); + $this->_conn->addColumn("users", "age", 'integer'); + $this->_conn->addColumn("users", "height", 'float'); + $this->_conn->addColumn("users", "wealth", 'decimal', array('precision' => '30', 'scale' => '10')); + $this->_conn->addColumn("users", "birthday", 'datetime'); + $this->_conn->addColumn("users", "favorite_day", 'date'); + $this->_conn->addColumn("users", "moment_of_truth", 'datetime'); + $this->_conn->addColumn("users", "male", 'boolean'); + + $this->_conn->insert('INSERT INTO users (first_name, last_name, bio, age, height, wealth, birthday, favorite_day, moment_of_truth, male, company_id) ' . + "VALUES ('bob', 'bobsen', 'I was born ....', 18, 1.78, 12345678901234567890.0123456789, '2005-01-01 12:23:40', '1980-03-05', '1582-10-10 21:40:18', 1, 1)"); + + $bob = (object)$this->_conn->selectOne('SELECT * FROM users'); + $this->assertEquals('bob', $bob->first_name); + $this->assertEquals('bobsen', $bob->last_name); + $this->assertEquals('I was born ....', $bob->bio); + $this->assertEquals(18, $bob->age); + + // Test for 30 significent digits (beyond the 16 of float), 10 of them + // after the decimal place. + $this->assertEquals('12345678901234567890.0123456789', $bob->wealth); + $this->assertEquals(1, $bob->male); + + // @todo - type casting + } + + public function testNativeDatabaseTypes() + { + $types = $this->_conn->nativeDatabaseTypes(); + $this->assertEquals(array('name' => 'int', 'limit' => 11), $types['integer']); + } + + public function testUnabstractedDatabaseDependentTypes() + { + $this->_createTestUsersTable(); + $this->_conn->delete('DELETE FROM users'); + + $this->_conn->addColumn('users', 'intelligence_quotient', 'tinyint'); + $this->_conn->insert('INSERT INTO users (intelligence_quotient) VALUES (300)'); + + $jonnyg = (object)$this->_conn->selectOne('SELECT * FROM users'); + $this->assertEquals('127', $jonnyg->intelligence_quotient); + } + + public function testTableAliasLength() + { + $len = $this->_conn->tableAliasLength(); + $this->assertEquals(255, $len); + } + + public function testTableAliasFor() + { + $alias = $this->_conn->tableAliasFor('my_table_name'); + $this->assertEquals('my_table_name', $alias); + } + + public function testTables() + { + $tables = $this->_conn->tables(); + $this->assertTrue(count($tables) > 0); + $this->assertContains('unit_tests', $tables); + } + + public function testPrimaryKey() + { + $pk = $this->_conn->primaryKey('unit_tests'); + $this->assertEquals('id', (string)$pk); + $this->assertEquals(1, count($pk->columns)); + $this->assertEquals('id', $pk->columns[0]); + } + + public function testIndexes() + { + $indexes = $this->_conn->indexes('unit_tests'); + $this->assertEquals(3, count($indexes)); + + // unique index + $col = array('integer_value'); + $this->assertEquals('unit_tests', $indexes[0]->table); + $this->assertEquals('integer_value', $indexes[0]->name); + $this->assertEquals(true, $indexes[0]->unique); + $this->assertEquals($col, $indexes[0]->columns); + + // normal index + $col = array('string_value'); + $this->assertEquals('unit_tests', $indexes[1]->table); + $this->assertEquals('string_value', $indexes[1]->name); + $this->assertEquals(false, $indexes[1]->unique); + $this->assertEquals($col, $indexes[1]->columns); + + // multi-column index + $col = array('integer_value', 'string_value'); + $this->assertEquals('unit_tests', $indexes[2]->table); + $this->assertEquals('integer_string', $indexes[2]->name); + $this->assertEquals(false, $indexes[2]->unique); + $this->assertEquals($col, $indexes[2]->columns); + } + + public function testColumns() + { + $columns = $this->_conn->columns('unit_tests'); + $this->assertEquals(12, count($columns)); + + $col = $columns['id']; + $this->assertEquals('id', $col->getName()); + $this->assertEquals('integer', $col->getType()); + $this->assertEquals(false, $col->isNull()); + $this->assertEquals(10, $col->getLimit()); + $this->assertEquals(true, $col->isUnsigned()); + $this->assertEquals('', $col->getDefault()); + $this->assertEquals('int(10) unsigned', $col->getSqlType()); + $this->assertEquals(false, $col->isText()); + $this->assertEquals(true, $col->isNumber()); + } + + public function testCreateTable() + { + $this->_createTestTable('sports'); + + $sql = "SELECT id FROM sports WHERE id = 1"; + $this->assertEquals(1, $this->_conn->selectValue($sql)); + } + + public function testCreateTableNoPk() + { + $this->_createTestTable('sports', array('primaryKey' => false)); + + try { + $sql = "SELECT id FROM sports WHERE id = 1"; + $this->assertNull($this->_conn->selectValue($sql)); + } catch (Exception $e) { + return; + } + $this->fail("Expected exception for no pk"); + } + + public function testCreateTableWithNamedPk() + { + $this->_createTestTable('sports', array('primaryKey' => 'sports_id')); + + $sql = "SELECT sports_id FROM sports WHERE sports_id = 1"; + $this->assertEquals(1, $this->_conn->selectValue($sql)); + + try { + $sql = "SELECT id FROM sports WHERE id = 1"; + $this->assertNull($this->_conn->selectValue($sql)); + } catch (Exception $e) { + return; + } + $this->fail("Expected exception for wrong pk name"); + } + + public function testCreateTableWithSeparatePk() + { + $table = $this->_conn->createTable('testings'); + $table->column('foo', 'primaryKey'); + + $pkColumn = $table['foo']; + $this->assertEquals('`foo` int(10) UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY', $pkColumn->toSql()); + } + + public function testCreateTableCompositePk() + { + $table = $this->_conn->createTable('testings', array('primaryKey' => array('a_id', 'b_id'))); + $table->column('a_id', 'integer'); + $table->column('b_id', 'integer'); + $table->end(); + + $pk = $this->_conn->primaryKey('testings'); + $this->assertEquals(array('a_id', 'b_id'), $pk->columns); + } + + public function testCreateTableForce() + { + $this->_createTestTable('sports'); + $this->_createTestTable('sports', array('force' => true)); + + $sql = "SELECT id FROM sports WHERE id = 1"; + $this->assertEquals(1, $this->_conn->selectValue($sql)); + } + + public function testCreateTableTemporary() + { + $this->_createTestTable('sports', array('temporary' => true)); + + $sql = "SELECT id FROM sports WHERE id = 1"; + $this->assertEquals(1, $this->_conn->selectValue($sql)); + } + + public function testCreateTableAddsId() + { + $table = $this->_conn->createTable('testings'); + $table->column('foo', 'string'); + $table->end(); + + $columns = array(); + foreach ($this->_conn->columns('testings') as $col) { + $columns[] = $col->getName(); + } + sort($columns); + $this->assertEquals(array('foo', 'id'), $columns); + } + + public function testCreateTableWithNotNullColumn() + { + $table = $this->_conn->createTable('testings'); + $table->column('foo', 'string', array('null' => false)); + $table->end(); + + try { + $this->_conn->execute("INSERT INTO testings (foo) VALUES (NULL)"); + } catch (Exception $e) { return; } + $this->fail('Expected exception wasn\'t raised'); + } + + public function testCreateTableWithDefaults() + { + $table = $this->_conn->createTable('testings'); + $table->column('one', 'string', array('default' => 'hello')); + $table->column('two', 'boolean', array('default' => true)); + $table->column('three', 'boolean', array('default' => false)); + $table->column('four', 'integer', array('default' => 1)); + $table->end(); + + $columns = array(); + foreach ($this->_conn->columns('testings') as $col) { + $columns[$col->getName()] = $col; + } + + $this->assertEquals('hello', $columns['one']->getDefault()); + $this->assertTrue($columns['two']->getDefault()); + $this->assertFalse($columns['three']->getDefault()); + $this->assertEquals(1, $columns['four']->getDefault()); + } + + public function testCreateTableWithLimits() + { + $table = $this->_conn->createTable('testings'); + $table->column('foo', 'string', array('limit' => 80)); + $table->end(); + + $columns = array(); + foreach ($this->_conn->columns('testings') as $col) { + $columns[$col->getName()] = $col; + } + $this->assertEquals(80, $columns['foo']->getLimit()); + } + + public function testCreateTableWithBinaryColumn() + { + try { + $table = $this->_conn->createTable('binary_testings'); + $table->column('data', 'binary', array('null' => false)); + $table->end(); + } catch (Exception $e) { $this->fail('Unexepected exception raised'); } + + $columns = $this->_conn->columns('binary_testings'); + + foreach ($columns as $c) { + if ($c->getName() == 'data') { $dataColumn = $c; } + } + $this->assertEquals('', $dataColumn->getDefault()); + } + + public function testRenameTable() + { + // Simple rename then select test + $this->_createTestTable('sports'); + $this->_conn->renameTable('sports', 'my_sports'); + + $sql = "SELECT id FROM my_sports WHERE id = 1"; + $this->assertEquals("1", $this->_conn->selectValue($sql)); + + // Make sure the old table name isn't still there + try { + $sql = "SELECT id FROM sports WHERE id = 1"; + $this->_conn->execute($sql); + } catch (Exception $e) { + return; + } + $this->fail("Table exists where it shouldn't have"); + + // Rename then insert test + $table = $this->_conn->createTable('octopuses'); + $table->column('url', 'string'); + $table->end(); + + $this->_conn->renameTable('octopuses', 'octopi'); + + $sql = "INSERT INTO octopi (id, url) VALUES (1, 'http://www.foreverflying.com/octopus-black7.jpg')"; + $this->_conn->execute($sql); + + $this->assertEquals('http://www.foreverflying.com/octopus-black7.jpg', + $this->_conn->selectValue("SELECT url FROM octopi WHERE id=1")); + + // Make sure the old table name isn't still there + try { + $sql = "SELECT id FROM octopuses WHERE id = 1"; + $this->_conn->execute($sql); + } catch (Exception $e) { + return; + } + $this->fail("Table exists where it shouldn't have"); + } + + public function testRenameTableWithAnIndex() + { + $table = $this->_conn->createTable('octopuses'); + $table->column('url', 'string'); + $table->end(); + $this->_conn->addIndex('octopuses', 'url'); + $this->_conn->renameTable('octopuses', 'octopi'); + + $sql = "INSERT INTO octopi (id, url) VALUES (1, 'http://www.foreverflying.com/octopus-black7.jpg')"; + $this->_conn->execute($sql); + + $this->assertEquals('http://www.foreverflying.com/octopus-black7.jpg', + $this->_conn->selectValue("SELECT url FROM octopi WHERE id=1")); + + $indexes = $this->_conn->indexes('octopi'); + $this->assertEquals('url', $indexes[0]->columns[0]); + } + + public function testDropTable() + { + $this->_createTestTable('sports'); + $this->_conn->dropTable('sports'); + + try { + $sql = "SELECT id FROM sports WHERE id = 1"; + $this->_conn->execute($sql); + } catch (Exception $e) { + return; + } + $this->fail("Table exists where it shouldn't have"); + } + + public function testAddColumn() + { + $this->_createTestTable('sports'); + $this->_conn->addColumn('sports', 'modified_at', 'date'); + $this->_conn->update("UPDATE sports SET modified_at = '2007-01-01'"); + + $sql = "SELECT modified_at FROM sports WHERE id = 1"; + $this->assertEquals("2007-01-01", $this->_conn->selectValue($sql)); + } + + public function testRemoveColumn() + { + $this->_createTestTable('sports'); + $sql = "SELECT name FROM sports WHERE id = 1"; + $this->assertEquals("mlb", $this->_conn->selectValue($sql)); + + $this->_conn->removeColumn('sports', 'name'); + + try { + $sql = "SELECT name FROM sports WHERE id = 1"; + $this->_conn->execute($sql); + } catch (Exception $e) { + return; + } + $this->fail("Column exists where it shouldn't have"); + } + + public function testChangeColumn() + { + $this->_createTestUsersTable(); + + $this->_conn->addColumn('users', 'age', 'integer'); + $oldColumns = $this->_conn->columns('users', "User Columns"); + + $found = false; + foreach ($oldColumns as $c) { + if ($c->getName() == 'age' && $c->getType() == 'integer') { $found = true; } + } + $this->assertTrue($found); + + $this->_conn->changeColumn('users', 'age', 'string'); + + $newColumns = $this->_conn->columns('users', "User Columns"); + + $found = false; + foreach ($newColumns as $c) { + if ($c->getName() == 'age' && $c->getType() == 'integer') { $found = true; } + } + $this->assertFalse($found); + $found = false; + foreach ($newColumns as $c) { + if ($c->getName() == 'age' && $c->getType() == 'string') { $found = true; } + } + $this->assertTrue($found); + + $found = false; + foreach ($oldColumns as $c) { + if ($c->getName() == 'approved' && $c->getType() == 'boolean' && + $c->getDefault() == true) { $found = true; } + } + $this->assertTrue($found); + + // changeColumn() throws exception on error + $this->_conn->changeColumn('users', 'approved', 'boolean', array('default' => false)); + + $newColumns = $this->_conn->columns('users', "User Columns"); + + $found = false; + foreach ($newColumns as $c) { + if ($c->getName() == 'approved' && $c->getType() == 'boolean' && + $c->getDefault() == true) { $found = true; } + } + $this->assertFalse($found); + + $found = false; + foreach ($newColumns as $c) { + if ($c->getName() == 'approved' && $c->getType() == 'boolean' && + $c->getDefault() == false) { $found = true; } + } + $this->assertTrue($found); + + // changeColumn() throws exception on error + $this->_conn->changeColumn('users', 'approved', 'boolean', array('default' => true)); + } + + public function testChangeColumnDefault() + { + $this->_createTestTable('sports'); + $beforeChange = $this->_getColumn('sports', 'name'); + $this->assertEquals('', $beforeChange->getDefault()); + + $this->_conn->changeColumnDefault('sports', 'name', 'test'); + + $afterChange = $this->_getColumn('sports', 'name'); + $this->assertEquals('test', $afterChange->getDefault()); + } + + public function testChangeColumnType() + { + $this->_createTestTable('sports'); + $beforeChange = $this->_getColumn('sports', 'is_college'); + $this->assertEquals('tinyint(1)', $beforeChange->getSqlType()); + + $this->_conn->changeColumn('sports', 'is_college', 'string'); + + $afterChange = $this->_getColumn('sports', 'is_college'); + $this->assertEquals('varchar(255)', $afterChange->getSqlType()); + } + + public function testChangeColumnLimit() + { + $this->_createTestTable('sports'); + $beforeChange = $this->_getColumn('sports', 'is_college'); + $this->assertEquals('tinyint(1)', $beforeChange->getSqlType()); + + $this->_conn->changeColumn('sports', 'is_college', 'string', + array('limit' => '40')); + + $afterChange = $this->_getColumn('sports', 'is_college'); + $this->assertEquals('varchar(40)', $afterChange->getSqlType()); + } + + public function testChangeColumnPrecisionScale() + { + $this->_createTestTable('sports'); + $beforeChange = $this->_getColumn('sports', 'is_college'); + $this->assertEquals('tinyint(1)', $beforeChange->getSqlType()); + + $this->_conn->changeColumn('sports', 'is_college', 'decimal', + array('precision' => '5', 'scale' => '2')); + + $afterChange = $this->_getColumn('sports', 'is_college'); + $this->assertEquals('decimal(5,2)', $afterChange->getSqlType()); + } + + public function testChangeColumnUnsigned() + { + $table = $this->_conn->createTable('testings'); + $table->column('foo', 'integer'); + $table->end(); + + $beforeChange = $this->_getColumn('testings', 'foo'); + $this->assertFalse($beforeChange->isUnsigned()); + + $this->_conn->execute("INSERT INTO testings (id, foo) VALUES (1, -1)"); + + $this->_conn->changeColumn('testings', 'foo', 'integer', array('unsigned' => true)); + + $afterChange = $this->_getColumn('testings', 'foo'); + $this->assertTrue($afterChange->isUnsigned()); + + $row = (object)$this->_conn->selectOne('SELECT * FROM testings'); + $this->assertEquals(0, $row->foo); + } + + public function testRenameColumn() + { + $this->_createTestUsersTable(); + + $this->_conn->renameColumn('users', 'first_name', 'nick_name'); + $this->assertTrue(in_array('nick_name', $this->_columnNames('users'))); + + $this->_createTestTable('sports'); + + $beforeChange = $this->_getColumn('sports', 'is_college'); + $this->assertEquals('tinyint(1)', $beforeChange->getSqlType()); + + $this->_conn->renameColumn('sports', 'is_college', 'is_renamed'); + + $afterChange = $this->_getColumn('sports', 'is_renamed'); + $this->assertEquals('tinyint(1)', $afterChange->getSqlType()); + } + + public function testRenameColumnWithSqlReservedWord() + { + $this->_createTestUsersTable(); + + $this->_conn->renameColumn('users', 'first_name', 'group'); + $this->assertTrue(in_array('group', $this->_columnNames('users'))); + } + + public function testAddIndex() + { + $this->_createTestUsersTable(); + + // Limit size of last_name and key columns to support Firebird index limitations + $this->_conn->addColumn('users', 'last_name', 'string', array('limit' => 100)); + $this->_conn->addColumn('users', 'key', 'string', array('limit' => 100)); + $this->_conn->addColumn('users', 'administrator', 'boolean'); + + $this->_conn->addIndex('users', 'last_name'); + $this->_conn->removeIndex('users', 'last_name'); + + $this->_conn->addIndex('users', array('last_name', 'first_name')); + $this->_conn->removeIndex('users', array('column' => array('last_name', 'first_name'))); + + $this->_conn->addIndex('users', array('last_name', 'first_name')); + $this->_conn->removeIndex('users', array('name' => 'index_users_on_last_name_and_first_name')); + + $this->_conn->addIndex('users', array('last_name', 'first_name')); + $this->_conn->removeIndex('users', 'last_name_and_first_name'); + + // quoting + $this->_conn->addIndex('users', array('key'), array('name' => 'key_idx', 'unique' => true)); + $this->_conn->removeIndex('users', array('name' => 'key_idx', 'unique' => true)); + + $this->_conn->addIndex('users', array('last_name', 'first_name', 'administrator'), + array('name' => "named_admin")); + + $this->_conn->removeIndex('users', array('name' => 'named_admin')); + } + + public function testAddIndexDefault() + { + $this->_createTestTable('sports'); + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNull($index); + + $this->_conn->addIndex('sports', 'is_college'); + + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNotNull($index); + } + + public function testAddIndexMultiColumn() + { + $this->_createTestTable('sports'); + $index = $this->_getIndex('sports', array('name', 'is_college')); + $this->assertNull($index); + + $this->_conn->addIndex('sports', array('name', 'is_college')); + + $index = $this->_getIndex('sports', array('name', 'is_college')); + $this->assertNotNull($index); + } + + public function testAddIndexUnique() + { + $this->_createTestTable('sports'); + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNull($index); + + $this->_conn->addIndex('sports', 'is_college', array('unique' => true)); + + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNotNull($index); + $this->assertTrue($index->unique); + } + + public function testAddIndexName() + { + $this->_createTestTable('sports'); + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNull($index); + + $this->_conn->addIndex('sports', 'is_college', array('name' => 'test')); + + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNotNull($index); + $this->assertEquals('test', $index->name); + } + + public function testRemoveIndexSingleColumn() + { + $this->_createTestTable('sports'); + + // add the index + $this->_conn->addIndex('sports', 'is_college'); + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNotNull($index); + + // remove it again + $this->_conn->removeIndex('sports', array('column' => 'is_college')); + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNull($index); + } + + public function testRemoveIndexMultiColumn() + { + $this->_createTestTable('sports'); + + // add the index + $this->_conn->addIndex('sports', array('name', 'is_college')); + $index = $this->_getIndex('sports', array('name', 'is_college')); + $this->assertNotNull($index); + + // remove it again + $this->_conn->removeIndex('sports', array('column' => array('name', 'is_college'))); + $index = $this->_getIndex('sports', array('name', 'is_college')); + $this->assertNull($index); + } + + public function testRemoveIndexByName() + { + $this->_createTestTable('sports'); + + // add the index + $this->_conn->addIndex('sports', 'is_college', array('name' => 'test')); + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNotNull($index); + + // remove it again + $this->_conn->removeIndex('sports', array('name' => 'test')); + $index = $this->_getIndex('sports', 'is_college'); + $this->assertNull($index); + } + + public function testIndexNameInvalid() + { + try { + $name = $this->_conn->indexName('sports'); + } catch (Horde_Db_Exception $e) { + return; + } + $this->fail("Adding an index with crappy options worked where it shouldn't have"); + } + + public function testIndexNameBySingleColumn() + { + $name = $this->_conn->indexName('sports', array('column' => 'is_college')); + $this->assertEquals('index_sports_on_is_college', $name); + } + + public function testIndexNameByMultiColumn() + { + $name = $this->_conn->indexName('sports', array('column' => + array('name', 'is_college'))); + $this->assertEquals('index_sports_on_name_and_is_college', $name); + } + + public function testIndexNameByName() + { + $name = $this->_conn->indexName('sports', array('name' => 'test')); + $this->assertEquals('test', $name); + } + + public function testTypeToSqlTypePrimaryKey() + { + $result = $this->_conn->typeToSql('primaryKey'); + $this->assertEquals('int(10) UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY', $result); + } + + public function testTypeToSqlTypeString() + { + $result = $this->_conn->typeToSql('string'); + $this->assertEquals('varchar(255)', $result); + } + + public function testTypeToSqlTypeText() + { + $result = $this->_conn->typeToSql('text'); + $this->assertEquals('text', $result); + } + + public function testTypeToSqlTypeBinary() + { + $result = $this->_conn->typeToSql('binary'); + $this->assertEquals('blob', $result); + } + + public function testTypeToSqlTypeFloat() + { + $result = $this->_conn->typeToSql('float'); + $this->assertEquals('float', $result); + } + + public function testTypeToSqlTypeDatetime() + { + $result = $this->_conn->typeToSql('datetime'); + $this->assertEquals('datetime', $result); + } + + public function testTypeToSqlTypeTimestamp() + { + $result = $this->_conn->typeToSql('timestamp'); + $this->assertEquals('datetime', $result); + } + + public function testTypeToSqlInt() + { + $result = $this->_conn->typeToSql('integer'); + $this->assertEquals('int(11)', $result); + } + + public function testTypeToSqlIntUnsigned() + { + $result = $this->_conn->typeToSql('integer', null, null, null, true); + $this->assertEquals('int(10) UNSIGNED', $result); + } + + public function testTypeToSqlIntLimit() + { + $result = $this->_conn->typeToSql('integer', '1'); + $this->assertEquals('int(1)', $result); + } + + public function testTypeToSqlDecimalPrecision() + { + $result = $this->_conn->typeToSql('decimal', null, '5'); + $this->assertEquals('decimal(5)', $result); + } + + public function testTypeToSqlDecimalScale() + { + $result = $this->_conn->typeToSql('decimal', null, '5', '2'); + $this->assertEquals('decimal(5, 2)', $result); + } + + public function testTypeToSqlBoolean() + { + $result = $this->_conn->typeToSql('boolean'); + $this->assertEquals('tinyint(1)', $result); + } + + public function testAddColumnOptions() + { + $result = $this->_conn->addColumnOptions("test", array()); + $this->assertEquals("test", $result); + } + + public function testAddColumnOptionsDefault() + { + $options = array('default' => '0'); + $result = $this->_conn->addColumnOptions("test", $options); + $this->assertEquals("test DEFAULT '0'", $result); + } + + public function testAddColumnOptionsNull() + { + $options = array('null' => true); + $result = $this->_conn->addColumnOptions("test", $options); + $this->assertEquals("test", $result); + } + + public function testAddColumnOptionsNotNull() + { + $options = array('null' => false); + $result = $this->_conn->addColumnOptions("test", $options); + $this->assertEquals("test NOT NULL", $result); + } + + public function testAddColumnNotNullWithoutDefault() + { + $table = $this->_conn->createTable('testings'); + $table->column('foo', 'string'); + $table->end(); + $this->_conn->addColumn('testings', 'bar', 'string', array('null' => false, 'default' => '')); + + try { + $this->_conn->execute("INSERT INTO testings (foo, bar) VALUES ('hello', NULL)"); + } catch (Exception $e) { return; } + $this->fail('Expected exception wasn\'t raised'); + } + + public function testAddColumnNotNullWithDefault() + { + $table = $this->_conn->createTable('testings'); + $table->column('foo', 'string'); + $table->end(); + + $this->_conn->execute("INSERT INTO testings (id, foo) VALUES ('1', 'hello')"); + + $this->_conn->addColumn('testings', 'bar', 'string', array('null' => false, 'default' => 'default')); + + try { + $this->_conn->execute("INSERT INTO testings (id, foo, bar) VALUES (2, 'hello', NULL)"); + } catch (Exception $e) { return; } + $this->fail('Expected exception wasn\'t raised'); + } + + public function testAddRemoveSingleField() + { + $this->_createTestUsersTable(); + + $this->assertFalse(in_array('last_name', $this->_columnNames('users'))); + + $this->_conn->addColumn('users', 'last_name', 'string'); + $this->assertTrue(in_array('last_name', $this->_columnNames('users'))); + + $this->_conn->removeColumn('users', 'last_name'); + $this->assertFalse(in_array('last_name', $this->_columnNames('users'))); + } + + public function testAddRename() + { + $this->_createTestUsersTable(); + + $this->_conn->delete('DELETE FROM users'); + + $this->_conn->addColumn('users', 'girlfriend', 'string'); + $this->_conn->insert("INSERT INTO users (girlfriend) VALUES ('bobette')"); + + $this->_conn->renameColumn('users', 'girlfriend', 'exgirlfriend'); + + $bob = (object)$this->_conn->selectOne('SELECT * FROM users'); + $this->assertEquals('bobette', $bob->exgirlfriend); + } + + public function testDistinct() + { + $result = $this->_conn->distinct("test"); + $this->assertEquals("DISTINCT test", $result); + } + + public function testAddOrderByForAssocLimiting() + { + $result = $this->_conn->addOrderByForAssocLimiting("SELECT * FROM documents ", + array('order' => 'name DESC')); + $this->assertEquals("SELECT * FROM documents ORDER BY name DESC", $result); + } + + + /*########################################################################## + # Table cache + ##########################################################################*/ + + public function testCachedTableIndexes() + { + // remove any current cache. + $this->_cache->set('tables/indexes/cache_table', ''); + $this->assertEquals('', $this->_cache->get('tables/indexes/cache_table')); + + $this->_createTestTable('cache_table'); + $idxs = $this->_conn->indexes('cache_table'); + + $this->assertNotEquals('', $this->_cache->get('tables/indexes/cache_table')); + } + + public function testCachedTableColumns() + { + // remove any current cache. + $this->_cache->set('tables/columns/cache_table', ''); + $this->assertEquals('', $this->_cache->get('tables/columns/cache_table')); + + $this->_createTestTable('cache_table'); + $cols = $this->_conn->columns('cache_table'); + + $this->assertNotEquals('', $this->_cache->get('tables/columns/cache_table')); + } + + + /*########################################################################## + # Protected + ##########################################################################*/ + + /** + * Create table to perform tests on + */ + protected function _createTestTable($name, $options=array()) + { + $table = $this->_conn->createTable($name, $options); + $table->column('name', 'string'); + $table->column('is_college', 'boolean'); + $table->end(); + + try { + // make sure table was created + $sql = "INSERT INTO $name + VALUES (1, 'mlb', 0)"; + $this->_conn->insert($sql); + } catch (Exception $e) {} + } + + protected function _createTestUsersTable() + { + $table = $this->_conn->createTable('users'); + $table->column('company_id', 'integer', array('limit' => 11)); + $table->column('name', 'string', array('limit' => 255, 'default' => '')); + $table->column('first_name', 'string', array('limit' => 40, 'default' => '')); + $table->column('approved', 'boolean', array('default' => true)); + $table->column('type', 'string', array('limit' => 255, 'default' => '')); + $table->column('created_at', 'datetime', array('default' => '0000-00-00 00:00:00')); + $table->column('created_on', 'date', array('default' => '0000-00-00')); + $table->column('updated_at', 'datetime', array('default' => '0000-00-00 00:00:00')); + $table->column('updated_on', 'date', array('default' => '0000-00-00')); + $table->end(); + } + + /** + * drop test tables + */ + protected function _dropTestTables() + { + $tables = array( + 'binary_testings', + 'cache_table', + 'my_sports', + 'octopi', + 'schema_info', + 'sports', + 'testings', + 'unit_tests', + 'users', + ); + + foreach ($tables as $table) { + try { + $this->_conn->dropTable($table); + } catch (Exception $e) {} + } + } + + protected function _columnNames($tableName) + { + $columns = array(); + foreach ($this->_conn->columns($tableName) as $c) { + $columns[] = $c->getName(); + } + return $columns; + } + + /** + * Get a column by name + */ + protected function _getColumn($table, $column) + { + foreach ($this->_conn->columns($table) as $col) { + if ($col->getName() == $column) return $col; + } + } + + /** + * Get an index by columns + */ + protected function _getIndex($table, $indexes) + { + $indexes = (array) $indexes; + sort($indexes); + + foreach ($this->_conn->indexes($table) as $index) { + $columns = $index->columns; + sort($columns); + if ($columns == $indexes) return $index; + } + } + +}