=== modified file 'CHANGELOG.txt' --- CHANGELOG.txt 2008-11-20 06:56:16 +0000 +++ CHANGELOG.txt 2008-11-23 03:21:48 +0000 @@ -7,6 +7,7 @@ Drupal 7.0, xxxx-xx-xx (development vers * Added query builders for INSERT, UPDATE, DELETE, MERGE, and SELECT queries. * Support for master/slave replication, transactions, multi-insert queries, delayed inserts, and other features. + * Added support for the SQLite database engine. - Security: * Protected cron.php -- cron will only run if the proper key is provided. * Implemented much stronger password hashes that are also compatible with the === added file 'includes/database/prefetch.inc' --- includes/database/prefetch.inc 1970-01-01 00:00:00 +0000 +++ includes/database/prefetch.inc 2008-11-23 04:19:45 +0000 @@ -0,0 +1,503 @@ + 'stdClass', + 'constructor_args' => array(), + 'object' => NULL, + 'column' => 0, + ); + + /** + * Holds the default fetch style. + * + * @var int + */ + protected $defaultFetchStyle = PDO::FETCH_OBJ; + + /** + * Holds supplementary default fetch options. + * + * @var Array + */ + protected $defaultFetchOptions = array( + 'class' => 'stdClass', + 'constructor_args' => array(), + 'object' => NULL, + 'column' => 0, + ); + + public function __construct(DatabaseConnection $connection, $query, Array $driver_options = array()) { + $this->dbh = $connection; + $this->queryString = $query; + $this->driverOptions = $driver_options; + } + + /** + * Executes a prepared statement. + * + * @param $args + * An array of values with as many elements as there are bound parameters in the SQL statement being executed. + * @param $options + * An array of options for this query. + * @return + * TRUE on success, or FALSE on failure. + */ + public function execute($args, $options) { + if (isset($options['fetch'])) { + if (is_string($options['fetch'])) { + // Default to an object. Note: db fields will be added to the object + // before the constructor is run. If you need to assign fields after + // the constructor is run, see http://drupal.org/node/315092. + $this->setFetchMode(PDO::FETCH_CLASS, $options['fetch']); + } + else { + $this->setFetchMode($options['fetch']); + } + } + $this->dbh->lastStatement = $this; + + $logger = $this->dbh->getLogger(); + if (!empty($logger)) { + $query_start = microtime(TRUE); + } + + // Prepare the query. + $statement = $this->getStatement($this->queryString, $args); + if (!$statement) { + $this->throwPDOException(); + } + + $return = $statement->execute($args); + if (!$return) { + $this->throwPDOException(); + } + + // Fetch all the data from the reply, in order to release any lock + // as soon as possible. + $this->rowCount = $statement->rowCount(); + $this->data = $statement->fetchAll(PDO::FETCH_ASSOC); + // Destroy the statement as soon as possible. + // @see DatabaseConnection_sqlite::PDOPrepare for explanation. + unset($statement); + + $this->resultRowCount = count($this->data); + + if ($this->resultRowCount) { + $this->columnNames = array_keys($this->data[0]); + $this->isValid = TRUE; + } + else { + $this->columnNames = array(); + $this->isValid = FALSE; + } + + if (!empty($logger)) { + $query_end = microtime(TRUE); + $logger->log($this, $args, $query_end - $query_start); + } + + // We will iterate this array so we need to make sure the array pointer is + // at the beginning. + reset($this->data); + + return $return; + } + + /** + * Throw a PDO Exception based on the last PDO error. + */ + protected function throwPDOException() { + $error_info = $this->dbh->errorInfo(); + // We rebuild a message formatted in the same way as PDO. + $exception = new PDOException("SQLSTATE[" . $error_info[0] . "]: General error " . $error_info[1] . ": " . $error_info[2]); + $exception->errorInfo = $error_info; + throw $exception; + } + + /** + * Grab a PDOStatement object from a given query and its arguments. + * + * Some drivers (including SQLite) will need to perform some preparation + * themselves to get the statement right. + * + * @param $query + * The query. + * @param Array $args + * An array of arguments. + * @return + * A PDOStatement object. + */ + protected function getStatement($query, &$args = array()) { + return $this->dbh->prepare($query); + } + + /** + * Return the object's SQL query string. + */ + public function getQueryString() { + return $this->queryString; + } + + /** + * @see PDOStatement::setFetchMode. + */ + public function setFetchMode($fetchStyle, $a2 = NULL, $a3 = NULL) { + $this->defaultFetchStyle = $fetchStyle; + switch ($fetchStyle) { + case PDO::FETCH_CLASS: + $this->defaultFetchOptions['class'] = $a2; + if ($a3) { + $this->defaultFetchOptions['constructor_args'] = $a3; + } + break; + case PDO::FETCH_COLUMN: + $this->defaultFetchOptions['column'] = $a2; + break; + case PDO::FETCH_INTO: + $this->defaultFetchOptions['object'] = $a2; + break; + } + + // Set the values for the next fetch. + $this->fetchStyle = $this->defaultFetchStyle; + $this->fetchOptions = $this->defaultFetchOptions; + } + + /** + * Return the current row formatted according to the current fetch style. + * + * This is the core method of this class. It grabs the value at the current + * array position in $this->data and format it according to $this->fetchStyle + * and $this->fetchMode. + * + * @return + * The current row formatted as requested. + */ + public function current() { + $row = current($this->data); + if ($row !== FALSE) { + switch ($this->fetchStyle) { + case PDO::FETCH_ASSOC: + return $row; + case PDO::FETCH_BOTH: + return $row + array_values($row); + case PDO::FETCH_NUM: + return array_values($row); + case PDO::FETCH_LAZY: + // We do not do lazy as everything is fetched already. Fallback to + // PDO::FETCH_OBJ. + case PDO::FETCH_OBJ: + return (object) $row; + case PDO::FETCH_CLASS | PDO::FETCH_CLASSTYPE: + $class_name = array_unshift($row); + // Deliberate no break. + case PDO::FETCH_CLASS: + if (!isset($class_name)) { + $class_name = $this->fetchOptions['class']; + } + if (count($this->fetchOptions['constructor_args'])) { + $reflector = new ReflectionClass($class_name); + $result = $reflector->newInstanceArgs($this->fetchOptions['constructor_args']); + } + else { + $result = new $class_name(); + } + foreach ($row as $k => $v) { + $result->$k = $v; + } + return $result; + case PDO::FETCH_INTO: + foreach ($row as $k => $v) { + $this->fetchOptions['object']->$k = $v; + } + return $this->fetchOptions['object']; + case PDO::FETCH_COLUMN: + if (isset($this->columnNames[$this->fetchOptions['column']])) { + return $row[$k][$this->columnNames[$this->fetchOptions['column']]]; + } + else { + return; + } + } + } + } + + /* Implementations of Iterator. */ + + public function key() { + return key($this->data); + } + + public function rewind() { + reset($this->data); + if (count($this->data)) { + $this->isValid = TRUE; + } + } + + public function next() { + // We fetch rows as PDO::FETCH_ASSOC in execute(), + // so no element of the array can ever be FALSE. + if (next($this->data) === FALSE) { + $this->isValid = FALSE; + } + } + + public function valid() { + return $this->isValid; + } + + /* Implementations of DatabaseStatementInterface. */ + + public function rowCount() { + return $this->rowCount; + } + + public function fetch($fetch_style = NULL, $cursor_orientation = PDO::FETCH_ORI_NEXT, $cursor_offset = NULL) { + if ($this->isValid) { + // Set the fetch parameter. + $this->fetchStyle = isset($fetch_style) ? $fetch_style : $this->defaultFetchStyle; + $this->fetchOptions = $this->defaultFetchOptions; + + // Grab the row in the format specified above. + $return = $this->current(); + // Advance the cursor. + $this->next(); + + // Reset the fetch parameters to the value stored using setFetchMode(). + $this->fetchStyle = $this->defaultFetchStyle; + $this->fetchOptions = $this->defaultFetchOptions; + return $return; + } + else { + return FALSE; + } + } + + public function fetchField($index = 0) { + if ($this->isValid && isset($this->columnNames[$index])) { + // We grab the value directly from $this->data, and format it. + $current = current($this->data); + $return = $current[$this->columnNames[$index]]; + $this->next(); + return $return; + } + else { + return FALSE; + } + } + + public function fetchObject($class_name = NULL, $constructor_args = array()) { + if ($this->isValid) { + if (!isset($class_name)) { + // Directly cast to an object to avoid a function call. + $result = (object) current($this->data); + } + else { + $this->fetchStyle = PDO::FETCH_CLASS; + $this->fetchOptions = array('constructor_args' => $constructor_args); + // Grab the row in the format specified above. + $result = $this->current(); + // Reset the fetch parameters to the value stored using setFetchMode(). + $this->fetchStyle = $this->defaultFetchStyle; + $this->fetchOptions = $this->defaultFetchOptions; + } + + $this->next(); + + return $result; + } + else { + return FALSE; + } + } + + public function fetchAssoc() { + if ($this->isValid) { + $result = current($this->data); + $this->next(); + return $result; + } + else { + return FALSE; + } + } + + public function fetchAll($fetch_style = NULL, $fetch_column = NULL, $constructor_args = NULL) { + $this->fetchStyle = isset($fetch_style) ? $fetch_style : $this->defaultFetchStyle; + $this->fetchOptions = $this->defaultFetchOptions; + if (isset($fetch_column)) { + $this->fetchOptions['column'] = $fetch_column; + } + if (isset($constructor_args)) { + $this->fetchOptions['constructor_args'] = $constructor_args; + } + + $result = array(); + // Traverse the array as PHP would have done. + while ($this->isValid) { + // Grab the row in the format specified above. + $result[] = $this->current(); + $this->next(); + } + + // Reset the fetch parameters to the value stored using setFetchMode(). + $this->fetchStyle = $this->defaultFetchStyle; + $this->fetchOptions = $this->defaultFetchOptions; + return $result; + } + + public function fetchCol($index = 0) { + if (isset($this->columnNames[$index])) { + $column = $this->columnNames[$index]; + $result = array(); + // Traverse the array as PHP would have done. + while ($this->isValid) { + $current = current($this->data); + $result[] = $current[$this->columnNames[$index]]; + $this->next(); + } + return $result; + } + else { + return array(); + } + } + + public function fetchAllKeyed($key_index = 0, $value_index = 1) { + if (!isset($this->columnNames[$key_index]) || !isset($this->columnNames[$value_index])) + return array(); + + $key = $this->columnNames[$key_index]; + $value = $this->columnNames[$value_index]; + + $result = array(); + // Traverse the array as PHP would have done. + while ($this->isValid) { + $row = current($this->data); + $result[$row[$key]] = $row[$value]; + $this->next(); + } + return $result; + } + + public function fetchAllAssoc($key, $fetch_style = PDO::FETCH_OBJ) { + $this->fetchStyle = $fetch_style; + $this->fetchOptions = $this->defaultFetchOptions; + + $result = array(); + // Traverse the array as PHP would have done. + while ($this->isValid) { + // Grab the row in its raw PDO::FETCH_ASSOC format. + $row = current($this->data); + // Grab the row in the format specified above. + $result_row = $this->current(); + $result[$row[$key]] = $result_row; + $this->next(); + } + + // Reset the fetch parameters to the value stored using setFetchMode(). + $this->fetchStyle = $this->defaultFetchStyle; + $this->fetchOptions = $this->defaultFetchOptions; + return $result; + } + +} + +/** + * @} End of "ingroup database". + */ + === added directory 'includes/database/sqlite' === added file 'includes/database/sqlite/database.inc' --- includes/database/sqlite/database.inc 1970-01-01 00:00:00 +0000 +++ includes/database/sqlite/database.inc 2008-11-23 04:23:02 +0000 @@ -0,0 +1,263 @@ +transactionSupport = isset($connection_options['transactions']) ? $connection_options['transactions'] : TRUE; + + parent::__construct('sqlite:'. $connection_options['database'], '', '', $connection_options); + + $this->exec('PRAGMA encoding="UTF-8"'); + + // Create functions needed by SQLite. + $this->sqliteCreateFunction('if', array($this, 'sqlFunctionIf')); + $this->sqliteCreateFunction('greatest', array($this, 'sqlFunctionGreatest')); + $this->sqliteCreateFunction('pow', 'pow', 2); + $this->sqliteCreateFunction('length', 'strlen', 1); + $this->sqliteCreateFunction('concat', array($this, 'sqlFunctionConcat')); + $this->sqliteCreateFunction('substring', array($this, 'sqlFunctionSubstring'), 3); + $this->sqliteCreateFunction('rand', array($this, 'sqlFunctionRand')); + } + + /** + * SQLite compatibility implementation for the IF() SQL function. + */ + public function sqlFunctionIf($condition, $expr1, $expr2 = NULL) { + return $condition ? $expr1 : $expr2; + } + + /** + * SQLite compatibility implementation for the GREATEST() SQL function. + */ + public function sqlFunctionGreatest() { + $args = func_get_args(); + foreach ($args as $k => $v) { + if (is_null($v)) { + unset($args); + } + } + if (count($args)) { + return max($args); + } + else { + return NULL; + } + } + + /** + * SQLite compatibility implementation for the CONCAT() SQL function. + */ + public function sqlFunctionConcat() { + $args = func_get_args(); + return implode('', $args); + } + + /** + * SQLite compatibility implementation for the SUBSTRING() SQL function. + */ + public function sqlFunctionSubstring($string, $from, $length) { + return substr($string, $from - 1, $length); + } + + /** + * SQLite compatibility implementation for the RAND() SQL function. + */ + public function sqlFunctionRand($seed = NULL) { + if (isset($seed)) { + mt_srand($seed); + } + return mt_rand() / mt_getrandmax(); + } + + /** + * SQLite-specific implementation of DatabaseConnection::prepare(). + * + * We don't use prepared statements at all at this stage. We just create + * a DatabaseStatement_sqlite object, that will create a PDOStatement + * using the semi-private PDOPrepare() method below. + */ + public function prepare($query, Array $options = array()) { + return new DatabaseStatement_sqlite($this, $query, $options); + } + + /** + * NEVER CALL THIS FUNCTION: YOU MIGHT DEADLOCK YOUR PHP PROCESS. + * + * This is a wrapper around the parent PDO::prepare method. However, as + * the PDO SQLite driver only closes SELECT statements when the PDOStatement + * destructor is called and SQLite does not allow data change (INSERT, + * UPDATE etc) on a table which has open SELECT statements, you should never + * call this function and keep a PDOStatement object alive as that can lead + * to a deadlock. This really, really should be private, but as + * DatabaseStatement_sqlite needs to call it, we have no other choice but to + * expose this function to the world. + */ + public function PDOPrepare($query, Array $options = array()) { + return parent::prepare($query, $options); + } + + public function queryRange($query, Array $args, $from, $count, Array $options = array()) { + return $this->query($query . ' LIMIT ' . $from . ', ' . $count, $args, $options); + } + + public function queryTemporary($query, Array $args, $tablename, Array $options = array()) { + return $this->query(preg_replace('/^SELECT/i', 'CREATE TEMPORARY TABLE ' . $tablename . ' AS SELECT', $query), $args, $options); + } + + public function driver() { + return 'sqlite'; + } + + public function databaseType() { + return 'sqlite'; + } + + public function supportsTransactions() { + return $this->transactionSupport; + } + + public function mapConditionOperator($operator) { + // We don't want to override any of the defaults. + return NULL; + } + + protected function prepareQuery($query) { + // It makes no sense to use the static prepared statement cache here, + // because all the work in our implementation is done in + // DatabaseStatement_sqlite::execute() and cannot be cached. + return $this->prepare($this->prefixTables($query)); + } + + /** + * @todo Remove this as soon as db_rewrite_sql() has been exterminated. + */ + public function distinctField($table, $field, $query) { + $field_to_select = 'DISTINCT(' . $table . '.' . $field . ')'; + // (?= :count) + * fail. We replace numeric placeholders in the query ourselves to work + * around this bug. + * + * See http://bugs.php.net/bug.php?id=45259 for more details. + */ + protected function getStatement($query, &$args = array()) { + if (count($args)) { + // Check if $args is a simple numeric array. + if (range(0, count($args) - 1) === array_keys($args)) { + // In that case, we have unnamed placeholders. + $count = 0; + $new_args = array(); + foreach ($args as $value) { + if (is_numeric($value)) { + $query = substr_replace($query, $value, strpos($query, '?'), 1); + } + else { + $placeholder = ':db_statement_placeholder_' . $count++; + $query = substr_replace($query, $placeholder, strpos($query, '?'), 1); + $new_args[$placeholder] = $value; + } + } + $args = $new_args; + } + else { + // Else, this is using named placeholders. + foreach ($args as $placeholder => $value) { + if (is_numeric($value)) { + $query = str_replace($placeholder, $value, $query); + unset($args[$placeholder]); + } + } + } + } + + return $this->dbh->PDOPrepare($query); + } + + public function execute($args, $options) { + try { + $return = parent::execute($args, $options); + } + catch (PDOException $e) { + if (!empty($e->errorInfo[1]) && $e->errorInfo[1] === 17) { + // The schema has changed. SQLite specifies that we must resend the query. + $return = parent::execute($args, $options); + } + else { + // Rethrow the exception. + throw $e; + } + } + + // In some weird cases, SQLite will prefix some column names by the name + // of the table. We post-process the data, by renaming the column names + // using the same convention as MySQL and PostgreSQL. + $rename_columns = array(); + foreach ($this->columnNames as $k => $column) { + if (preg_match("/^.*\.(.*)$/", $column, $matches)) { + $rename_columns[$column] = $matches[1]; + $this->columnNames[$k] = $matches[1]; + } + } + if ($rename_columns) { + foreach ($this->data as $k => $row) { + foreach ($rename_columns as $old_column => $new_column) { + $this->data[$k][$new_column] = $this->data[$k][$old_column]; + unset($this->data[$k][$old_column]); + } + } + } + + // We will iterate this array so we need to make sure the array pointer is + // at the beginning. + reset($this->data); + + return $return; + } + +} + +/** + * @} End of "ingroup database". + */ === added file 'includes/database/sqlite/install.inc' --- includes/database/sqlite/install.inc 1970-01-01 00:00:00 +0000 +++ includes/database/sqlite/install.inc 2008-11-23 03:22:48 +0000 @@ -0,0 +1,15 @@ +insertFields) + count($this->defaultFields) == 0) { + return NULL; + } + if (count($this->insertFields)) { + return parent::execute(); + } + else { + return $this->connection->query('INSERT INTO {'. $this->table .'} DEFAULT VALUES', array(), $this->queryOptions); + } + } + + public function __toString() { + // Produce as many generic placeholders as necessary. + $placeholders = array_fill(0, count($this->insertFields), '?'); + return 'INSERT INTO {'. $this->table .'} ('. implode(', ', $this->insertFields) .') VALUES ('. implode(', ', $placeholders) .')'; + } + +} + +/** + * SQLite specific implementation of UpdateQuery. + * + * SQLite counts all the rows that match the conditions as modified, even if they + * will not be affected by the query. We workaround this by ensuring that + * we don't select those rows. + * + * A query like this one: + * UPDATE test SET name = 'newname' WHERE tid = 1 + * will become: + * UPDATE test SET name = 'newname' WHERE tid = 1 AND name <> 'newname' + */ +class UpdateQuery_sqlite extends UpdateQuery { + + /** + * Helper function that removes the fields that are already in a condition. + * + * @param $fields + * The fields. + * @param QueryConditionInterface $condition + * A database condition. + */ + protected function removeFieldsInCondition(&$fields, QueryConditionInterface $condition) { + foreach ($condition->conditions() as $child_condition) { + if ($child_condition['field'] instanceof QueryConditionInterface) { + $this->removeFieldsInCondition($fields, $child_condition['field']); + } + else { + unset($fields[$child_condition['field']]); + } + } + } + + public function execute() { + // Get the fields used in the update query, and remove those that are already + // in the condition. + $fields = $this->expressionFields + $this->fields; + $this->removeFieldsInCondition($fields, $this->condition); + + // Add the inverse of the fields to the condition. + $condition = db_or(); + foreach ($fields as $field => $data) { + if (is_array($data)) { + // The field is an expression. + $condition->condition($field, $data['expression'], '<>'); + // The IS NULL operator is badly managed by DatabaseCondition. + $condition->where($field . ' IS NULL'); + } + else if (is_null($data)) { + // The field will be set to NULL. + // The IS NULL operator is badly managed by DatabaseCondition. + $condition->where($field . ' IS NOT NULL'); + } + else { + $condition->condition($field, $data, '<>'); + // The IS NULL operator is badly managed by DatabaseCondition. + $condition->where($field . ' IS NULL'); + } + } + if (count($condition)) { + $condition->compile($this->connection); + $this->condition->where((string) $condition, $condition->arguments()); + } + return parent::execute(); + } + +} + +/** + * SQLite specific implementation of DeleteQuery. + * + * When the WHERE is omitted from a DELETE statement and the table being deleted + * has no triggers, SQLite uses an optimization to erase the entire table content + * without having to visit each row of the table individually. + * + * Prior to SQLite 3.6.5, SQLite does not return the actual number of rows deleted + * by that optimized "truncate" optimization. + */ +class DeleteQuery_sqlite extends DeleteQuery { + public function execute() { + if (!count($this->condition)) { + $total_rows = $this->connection->query('SELECT COUNT(*) FROM {' . $this->connection->escapeTable($this->table) . '}')->fetchField(); + parent::execute(); + return $total_rows; + } + else { + return parent::execute(); + } + } +} + +/** + * @} End of "ingroup database". + */ === added file 'includes/database/sqlite/schema.inc' --- includes/database/sqlite/schema.inc 1970-01-01 00:00:00 +0000 +++ includes/database/sqlite/schema.inc 2008-11-23 04:39:23 +0000 @@ -0,0 +1,572 @@ +connection->query("SELECT name FROM sqlite_master WHERE type = 'table' AND name LIKE '{" . $table . "}'", array(), array())->fetchField(); + } + + public function columnExists($table, $column) { + $schema = $this->introspectSchema($table); + return !empty($schema['fields'][$column]); + } + + /** + * Generate SQL to create a new table from a Drupal schema definition. + * + * @param $name + * The name of the table to create. + * @param $table + * A Schema API table definition array. + * @return + * An array of SQL statements to create the table. + */ + public function createTableSql($name, $table) { + $sql = array(); + $sql[] = "CREATE TABLE {" . $name . "} (\n" . $this->createColumsSql($name, $table) . "\n);\n"; + return array_merge($sql, $this->createIndexSql($name, $table)); + } + + /** + * Build the SQL expression for indexes. + */ + protected function createIndexSql($tablename, $schema) { + $sql = array(); + if (!empty($schema['unique keys'])) { + foreach ($schema['unique keys'] as $key => $fields) { + $sql[] = 'CREATE UNIQUE INDEX {' . $tablename . '}_' . $key . ' ON {' . $tablename . '} (' . $this->createKeySql($fields) . "); \n"; + } + } + if (!empty($schema['indexes'])) { + foreach ($schema['indexes'] as $index => $fields) { + $sql[] = 'CREATE INDEX {' . $tablename . '}_' . $index . ' ON {' . $tablename . '} (' . $this->createKeySql($fields) . "); \n"; + } + } + return $sql; + } + + /** + * Build the SQL expression for creating columns. + */ + protected function createColumsSql($tablename, $schema) { + $sql = ""; + + // Add the SQL statement for each field. + foreach ($schema['fields'] as $name => $field) { + if ($field['type'] == 'serial') { + if (isset($schema['primary key']) && ($key = array_search($name, $schema['primary key'])) !== false) { + unset($schema['primary key'][$key]); + } + } + $sql .= $this->createFieldSql($name, $this->processField($field)) . ", \n"; + } + + // Process keys. + if (!empty($schema['primary key'])) { + $sql .= " PRIMARY KEY (" . $this->createKeySql($schema['primary key']) . "), \n"; + } + + // Remove the last comma and space. + $sql = substr($sql, 0, -3); + return $sql; + } + + /** + * Build the SQL expression for keys. + */ + protected function createKeySql($fields) { + $ret = array(); + foreach ($fields as $field) { + if (is_array($field)) { + $ret[] = $field[0]; + } + else { + $ret[] = $field; + } + } + return implode(', ', $ret); + } + + /** + * Set database-engine specific properties for a field. + * + * @param $field + * A field description array, as specified in the schema documentation. + */ + protected function processField($field) { + if (!isset($field['size'])) { + $field['size'] = 'normal'; + } + // Set the correct database-engine specific datatype. + if (!isset($field['sqlite_type'])) { + $map = $this->getFieldTypeMap(); + $field['sqlite_type'] = $map[$field['type'] . ':' . $field['size']]; + } + + if ($field['type'] == 'serial') { + $field['auto_increment'] = TRUE; + } + + return $field; + } + + /** + * Create an SQL string for a field to be used in table creation or alteration. + * + * Before passing a field out of a schema definition into this function it has + * to be processed by db_processField(). + * + * @param $name + * Name of the field. + * @param $spec + * The field specification, as per the schema data structure format. + */ + protected function createFieldSql($name, $spec) { + if (!empty($spec['auto_increment'])) { + $sql = $name . " INTEGER PRIMARY KEY AUTOINCREMENT"; + } + else { + $sql = $name . " " . $spec['sqlite_type']; + + if (isset($spec['length'])) { + $sql .= '(' . $spec['length'] . ')'; + } + + if (!empty($spec['not null'])) { + $sql .= ' NOT NULL'; + } + + if (isset($spec['default'])) { + if (is_string($spec['default'])) { + $spec['default'] = "'" . $spec['default'] . "'"; + } + $sql .= ' DEFAULT ' . $spec['default']; + } + + if (empty($spec['not null']) && !isset($spec['default'])) { + $sql .= ' DEFAULT NULL'; + } + } + return $sql; + } + + /** + * This maps a generic data type in combination with its data size + * to the engine-specific data type. + */ + public function getFieldTypeMap() { + // Put :normal last so it gets preserved by array_flip. This makes + // it much easier for modules (such as schema.module) to map + // database types back into schema types. + $map = array( + 'varchar:normal' => 'VARCHAR', + + 'text:tiny' => 'TEXT', + 'text:small' => 'TEXT', + 'text:medium' => 'TEXT', + 'text:big' => 'TEXT', + 'text:normal' => 'TEXT', + + 'serial:tiny' => 'INTEGER', + 'serial:small' => 'INTEGER', + 'serial:medium' => 'INTEGER', + 'serial:big' => 'INTEGER', + 'serial:normal' => 'INTEGER', + + 'int:tiny' => 'INTEGER', + 'int:small' => 'INTEGER', + 'int:medium' => 'INTEGER', + 'int:big' => 'INTEGER', + 'int:normal' => 'INTEGER', + + 'float:tiny' => 'FLOAT', + 'float:small' => 'FLOAT', + 'float:medium' => 'FLOAT', + 'float:big' => 'FLOAT', + 'float:normal' => 'FLOAT', + + 'numeric:normal' => 'NUMERIC', + + 'blob:big' => 'BLOB', + 'blob:normal' => 'BLOB', + + 'datetime:normal' => 'TIMESTAMP', + ); + return $map; + } + + /** + * Rename a table. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be renamed. + * @param $new_name + * The new name for the table. + */ + public function renameTable(&$ret, $table, $new_name) { + $ret[] = update_sql('ALTER TABLE {' . $table . '} RENAME TO {' . $new_name . '}'); + } + + /** + * Drop a table. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be dropped. + */ + public function dropTable(&$ret, $table) { + $ret[] = update_sql('DROP TABLE {' . $table . '}'); + } + + /** + * Add a new field to a table. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * Name of the table to be altered. + * @param $field + * Name of the field to be added. + * @param $spec + * The field specification array, as taken from a schema definition. + */ + public function addField(&$ret, $table, $field, $spec, $keys_new = array()) { + // TODO: $keys_new is not supported yet. + $query = 'ALTER TABLE {' . $table . '} ADD '; + $query .= $this->createFieldSql($field, $this->processField($spec)); + $ret[] = update_sql($query); + } + + /** + * Create a table with a new schema containing the old content. + * + * As SQLite does not support ALTER TABLE (with a few exceptions) it is + * necessary to create a new table and copy over the old content. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * Name of the table to be altered. + * @param $new_schema + * The new schema array for the table. + */ + protected function alterTable(&$ret, $table, $new_schema) { + $i = 0; + do { + $new_table = $table . '_' . $i++; + } while ($this->tableExists($new_table)); + $this->createTable($ret, $new_table, $new_schema); + $fields = implode(', ', array_keys($new_schema['fields'])); + $ret[] = update_sql('INSERT INTO {' . $new_table . "} ($fields) SELECT $fields FROM {" . $table . '}'); + $old_count = db_query('SELECT COUNT(*) FROM {' . $table . '}')->fetchField(); + $new_count = db_query('SELECT COUNT(*) FROM {' . $new_table . '}')->fetchField(); + if ($old_count == $new_count) { + do { + $temp_table = $table . '_' . $i++; + } while ($this->tableExists($temp_table)); + $this->renameTable($ret, $table, $temp_table); + $this->renameTable($ret, $new_table, $table); + $this->dropTable($ret, $temp_table); + } + } + + /** + * Find out the schema of a table. + * + * This function uses introspection methods provided by the database to + * create a schema array. This is useful, for example, during update when + * the old schema is not available. + * + * @param $table + * Name of the table. + * @return + * An array representing the schema, @see drupal_get_schema. + */ + protected function introspectSchema($table) { + $mapped_fields = array_flip($this->getFieldTypeMap()); + $schema = array(); + foreach (db_query("PRAGMA table_info('{" . $table . "}')") as $row) { + if (preg_match('/^([^(]+)\((.*)\)$/', $row->type, $matches)) { + $type = $matches[1]; + $length = $matches[2]; + } + else { + $type = $row->type; + $length = NULL; + } + if (isset($mapped_fields[$type])) { + list($type, $size) = explode(':', $mapped_fields[$type]); + $schema['fields'][$row->name] = array( + 'type' => $type, + 'size' => $size, + 'not null' => !empty($row->notnull), + 'default' => trim($row->dflt_value, "'"), + ); + if ($length) { + $schema['fields'][$row->name]['length'] = $length; + } + if ($row->pk) { + $schema['primary key'][] = $row->name; + } + } + else { + new Exception("Unable to parse the column type " . $row->type); + } + } + $indexes = array(); + foreach (db_query("PRAGMA index_list('{" . $table . "}')") as $row) { + if (strpos($row->name, 'sqlite_autoindex_') !== 0) { + $indexes[] = array( + 'schema_key' => $row->unique ? 'unique keys' : 'indexes', + 'name' => $row->name, + ); + } + } + $n = strlen($table) + 1; + foreach ($indexes as $index) { + $name = $index['name']; + $index_name = substr($name, $n); + foreach (db_query("PRAGMA index_info('$name')") as $row) { + $schema[$index['schema_key']][$index_name][] = $row->name; + } + } + return $schema; + } + + /** + * Drop a field. + * + * This implementation can't use ALTER TABLE directly, because SQLite only + * supports a limited subset of that command. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $field + * The field to be dropped. + */ + public function dropField(&$ret, $table, $field) { + $new_schema = $this->introspectSchema($table); + unset($new_schema['fields'][$field]); + foreach ($new_schema['indexes'] as $index => $fields) { + foreach ($fields as $key => $field_name) { + if ($field_name == $field) { + unset($new_schema['indexes'][$index][$key]); + } + } + // If this index has no more fields then remove it. + if (empty($new_schema['indexes'][$index])) { + unset($new_schema['indexes'][$index]); + } + } + $this->alterTable($ret, $table, $new_schema); + } + + /** + * Change a field definition. + * + * This implementation can't use ALTER TABLE directly, because SQLite only + * supports a limited subset of that command. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * Name of the table. + * @param $field + * Name of the field to change. + * @param $field_new + * New name for the field (set to the same as $field if you don't want to change the name). + * @param $spec + * The field specification for the new field. + * @param $keys_new + * Optional keys and indexes specification to be created on the + * table along with changing the field. The format is the same as a + * table specification but without the 'fields' element. + */ + public function changeField(&$ret, $table, $field, $field_new, $spec, $keys_new = array()) { + $new_schema = $this->introspectSchema($table); + unset($new_schema['fields'][$field]); + $new_schema['fields'][$field_new] = $spec; + if (isset($keys_new['primary keys'])) { + $new_schema['primary keys'] = $keys_new['primary keys']; + $keys_new['primary keys']; + } + foreach (array('unique keys', 'indexes') as $k) { + if (!empty($keys_new[$k])) { + $new_schema[$k] = $keys_new[$k] + $new_schema[$k]; + } + } + $this->alterTable($ret, $table, $new_schema); + } + + /** + * Add an index. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $name + * The name of the index. + * @param $fields + * An array of field names. + */ + public function addIndex(&$ret, $table, $name, $fields) { + $schema['indexes'][$name] = $fields; + $ret[] = update_sql($this->createIndexSql($table, $schema)); + } + + /** + * Drop an index. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $name + * The name of the index. + */ + public function dropIndex(&$ret, $table, $name) { + $ret[] = update_sql('DROP INDEX ' . '{' . $table . '}_' . $name); + } + + /** + * Add a unique key. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $name + * The name of the key. + * @param $fields + * An array of field names. + */ + public function addUniqueKey(&$ret, $table, $name, $fields) { + $schema['unique keys'][$name] = $fields; + $ret[] = update_sql($this->createIndexSql($table, $schema)); + + } + + /** + * Drop a unique key. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $name + * The name of the key. + */ + public function dropUniqueKey(&$ret, $table, $name) { + $ret[] = update_sql('DROP INDEX ' . '{' . $table . '}_' . $name); + } + + /** + * Add a primary key. + * + * This implementation can't use ALTER TABLE directly, because SQLite only + * supports a limited subset of that command. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $fields + * Fields for the primary key. + */ + public function addPrimaryKey(&$ret, $table, $fields) { + $new_schema = $this->introspectSchema($table); + $new_schema['primary key'] = $fields; + $this->alterTable($ret, $table, $new_schema); + } + + /** + * Drop the primary key. + * + * This implementation can't use ALTER TABLE directly, because SQLite only + * supports a limited subset of that command.` + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + */ + public function dropPrimaryKey(&$ret, $table) { + $new_schema = $this->introspectSchema($table); + unset($new_schema['primary key']); + $this->alterTable($ret, $table, $new_schema); + } + + /** + * Set the default value for a field. + * + * This implementation can't use ALTER TABLE directly, because SQLite only + * supports a limited subset of that command. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $field + * The field to be altered. + * @param $default + * Default value to be set. NULL for 'default NULL'. + */ + public function fieldSetDefault(&$ret, $table, $field, $default) { + $new_schema = $this->introspectSchema($table); + $new_schema['fields'][$field]['default'] = $default; + $this->alterTable($ret, $table, $new_schema); + } + + /** + * Set a field to have no default value. + * + * This implementation can't use ALTER TABLE directly, because SQLite only + * supports a limited subset of that command. + * + * @param $ret + * Array to which query results will be added. + * @param $table + * The table to be altered. + * @param $field + * The field to be altered. + */ + public function fieldSetNoDefault(&$ret, $table, $field) { + $new_schema = $this->introspectSchema($table); + unset($new_schema['fields'][$field]['default']); + $this->alterTable($ret, $table, $new_schema); + } + + /** + * Find all tables that are like the specified base table name. + * + * @param $table_expression + * An SQL expression, for example "simpletest%" (without the quotes). + * BEWARE: this is not prefixed, the caller should take care of that. + * @return + * Array, both the keys and the values are the matching tables. + */ + public function findTables($table_expression) { + $result = db_query("SELECT name FROM sqlite_master WHERE name LIKE :table_name", array( + ':table_name' => $table_expression, + )); + return $result->fetchAllKeyed(0, 0); + } +}