From b3b82810a0593fabc4fb78d5993dc7b61947d205 Mon Sep 17 00:00:00 2001 From: Damian Mooyman Date: Wed, 3 Apr 2013 17:49:59 +1300 Subject: [PATCH] API Upgraded module to use new database ORM API Use SQLite3::version to directly get connection version --- _config.php | 36 +- _config/connectors.yml | 29 + _config/sqllite3.yml | 4 + _configure_database.php | 14 + _register_database.php | 45 + code/SQLite3Connector.php | 187 ++++ code/SQLite3Database.php | 1114 +++----------------- code/SQLite3Query.php | 62 ++ code/SQLite3QueryBuilder.php | 49 + code/SQLite3SchemaManager.php | 605 +++++++++++ code/SQLiteDatabaseConfigurationHelper.php | 179 ++-- code/SQLitePDODatabase.php | 178 ---- 12 files changed, 1245 insertions(+), 1257 deletions(-) create mode 100644 _config/connectors.yml create mode 100644 _config/sqllite3.yml create mode 100644 _configure_database.php create mode 100644 _register_database.php create mode 100644 code/SQLite3Connector.php create mode 100644 code/SQLite3Query.php create mode 100644 code/SQLite3QueryBuilder.php create mode 100644 code/SQLite3SchemaManager.php delete mode 100644 code/SQLitePDODatabase.php diff --git a/_config.php b/_config.php index dc121fc..6820f12 100644 --- a/_config.php +++ b/_config.php @@ -1,37 +1,3 @@ array( + 'title' => 'Directory path
Absolute path to directory, writeable by the webserver user.
' + . 'Recommended to be outside of your webroot
', + 'default' => dirname(dirname(__FILE__)) . DIRECTORY_SEPARATOR . 'assets' . DIRECTORY_SEPARATOR . '.sqlitedb' + ), + 'database' => array( + 'title' => 'Database filename (extension .sqlite)', + 'default' => 'database.sqlite' + ) +); + +// Basic SQLLite3 Database +DatabaseAdapterRegistry::register( + array( + 'class' => 'SQLite3Database', + 'title' => 'SQLite 3.3+ (using SQLite3)', + 'helperPath' => dirname(__FILE__).'/code/SQLiteDatabaseConfigurationHelper.php', + 'supported' => class_exists('SQLite3'), + 'missingExtensionText' => 'The SQLite3 + PHP Extension is not available. Please install or enable it of them and refresh this page.', + 'fields' => array_merge($sqliteDatabaseAdapterRegistryFields, array('key' => array( + 'title' => 'Encryption key
This function is experimental and requires configuration of an ' + . 'encryption module', + 'default' => '' + ))) + ) +); + +// PDO database +DatabaseAdapterRegistry::register( + array( + 'class' => 'SQLite3PDODatabase', + 'title' => 'SQLite 3.3+ (using PDO)', + 'helperPath' => dirname(__FILE__).'/code/SQLiteDatabaseConfigurationHelper.php', + 'supported' => (class_exists('PDO') && in_array('sqlite', PDO::getAvailableDrivers())), + 'missingExtensionText' => + 'Either the PDO Extension or the + SQLite3 PDO Driver + are unavailable. Please install or enable these and refresh this page.', + 'fields' => $sqliteDatabaseAdapterRegistryFields + ) +); diff --git a/code/SQLite3Connector.php b/code/SQLite3Connector.php new file mode 100644 index 0000000..135bb0e --- /dev/null +++ b/code/SQLite3Connector.php @@ -0,0 +1,187 @@ +dbConn = empty($parameters['key']) + ? new SQLite3($file, SQLITE3_OPEN_READWRITE | SQLITE3_OPEN_CREATE) + : new SQLite3($file, SQLITE3_OPEN_READWRITE | SQLITE3_OPEN_CREATE, $parameters['key']); + $this->dbConn->busyTimeout(60000); + $this->databaseName = $parameters['database']; + } + + public function affectedRows() { + return $this->dbConn->changes(); + } + + public function getGeneratedID($table) { + return $this->dbConn->lastInsertRowID(); + } + + public function getLastError() { + $message = $this->dbConn->lastErrorMsg(); + return $message === 'not an error' ? null : $message; + } + + public function getSelectedDatabase() { + return $this->databaseName; + } + + public function getVersion() { + $version = SQLite3::version(); + return trim($version['versionString']); + } + + public function isActive() { + return $this->databaseName && $this->dbConn; + } + + /** + * Prepares the list of parameters in preparation for passing to mysqli_stmt_bind_param + * + * @param array $parameters List of parameters + * @return array List of parameters types and values + */ + public function parsePreparedParameters($parameters) { + $values = array(); + foreach($parameters as $value) { + $phpType = gettype($value); + $sqlType = null; + + // Allow overriding of parameter type using an associative array + if($phpType === 'array') { + $phpType = $value['type']; + $value = $value['value']; + } + + // Convert php variable type to one that makes mysqli_stmt_bind_param happy + // @see http://www.php.net/manual/en/mysqli-stmt.bind-param.php + switch($phpType) { + case 'boolean': + case 'integer': + $sqlType = SQLITE3_INTEGER; + break; + case 'float': // Not actually returnable from gettype + case 'double': + $sqlType = SQLITE3_FLOAT; + break; + case 'object': // Allowed if the object or resource has a __toString method + case 'resource': + case 'string': + $sqlType = SQLITE3_TEXT; + break; + case 'NULL': + $sqlType = SQLITE3_NULL; + break; + case 'blob': + $sqlType = SQLITE3_BLOB; + break; + case 'array': + case 'unknown type': + default: + user_error("Cannot bind parameter \"$value\" as it is an unsupported type ($phpType)", E_USER_ERROR); + break; + } + $values[] = array( + 'type' => $sqlType, + 'value' => $value + ); + } + return $values; + } + + public function preparedQuery($sql, $parameters, $errorLevel = E_USER_ERROR) { + // Check if we should only preview this query + if ($this->previewWrite($sql)) return; + + // Type check, identify, and prepare parameters for passing to the statement bind function + $parsedParameters = $this->parsePreparedParameters($parameters); + + // Benchmark query + $conn = $this->dbConn; + $handle = $this->benchmarkQuery($sql, function($sql) use($conn, $parsedParameters) { + + // Prepare statement + $statement = @$conn->prepare($sql); + if(empty($statement)) return null; + + // Bind all variables + for($i = 0; $i < count($parsedParameters); $i++) { + $value = $parsedParameters[$i]['value']; + $type = $parsedParameters[$i]['type']; + $statement->bindValue($i+1, $value, $type); + } + + // Run + return $statement->execute(); + }); + + // Check for errors + if (!$handle) { + $values = $this->parameterValues($parameters); + $this->databaseError($this->getLastError(), $errorLevel, $sql, $values); + return null; + } + + return new SQLite3Query($this, $handle); + } + + public function query($sql, $errorLevel = E_USER_ERROR) { + // Check if we should only preview this query + if ($this->previewWrite($sql)) return; + + // Benchmark query + $conn = $this->dbConn; + $handle = $this->benchmarkQuery($sql, function($sql) use($conn) { + return @$conn->query($sql); + }); + + // Check for errors + if (!$handle) { + $this->databaseError($this->getLastError(), $errorLevel, $sql); + return null; + } + + return new SQLite3Query($this, $handle); + } + + public function quoteString($value) { + return "'".$this->escapeString($value)."'"; + } + + public function escapeString($value) { + return $this->dbConn->escapeString($value); + } + + public function selectDatabase($name) { + if($name !== $this->databaseName) { + user_error("SQLite3Connector can't change databases. Please create a new database connection", E_USER_ERROR); + } + return true; + } + + public function unloadDatabase() { + $this->dbConn->close(); + $this->databaseName = null; + } +} diff --git a/code/SQLite3Database.php b/code/SQLite3Database.php index 04380ac..004bb3f 100644 --- a/code/SQLite3Database.php +++ b/code/SQLite3Database.php @@ -1,68 +1,79 @@ '"UTF-8"', + 'locking_mode' => 'NORMAL' + ); + + + /** + * Extension used to distinguish between sqllite database files and other files. + * Required to handle multiple databases. + * + * @return string + */ + public static function database_extension() { + return Config::inst()->get('SQLite3Database', 'database_extension'); + } + + /** + * Check if a database name has a valid extension + * + * @param string $name + * @return boolean + */ + public static function is_valid_database_name($name) { + $extension = self::database_extension(); + if(empty($extension)) return true; + + return substr_compare($name, $extension, -strlen($extension), strlen($extension)) === 0; + } /** * Connect to a SQLite3 database. * @param array $parameters An map of parameters, which should include: - * - database: The database to connect to + * - database: The database to connect to, with the correct file extension (.sqlite) * - path: the path to the SQLite3 database file * - key: the encryption key (needs testing) * - memory: use the faster In-Memory database for unit tests */ - public function __construct($parameters) { - //We will store these connection parameters for use elsewhere (ie, unit tests) - $this->parameters=$parameters; - $this->connectDatabase(); - - $this->database_original=$this->database; - } - - /* - * Uses whatever connection details are in the $parameters array to connect to a database of a given name - */ - function connectDatabase() { - $this->enum_map = array(); - $parameters = $this->parameters; + public function connect($parameters) { if(!empty($parameters['memory'])) { Deprecation::notice( @@ -70,54 +81,76 @@ class SQLite3Database extends SS_Database { "\$databaseConfig['memory'] is deprecated. Use \$databaseConfig['path'] = ':memory:' instead.", Deprecation::SCOPE_GLOBAL ); + unset($parameters['memory']); $parameters['path'] = ':memory:'; } - $dbName = !isset($this->database) ? $parameters['database'] : $this->database; - $file = $parameters['path']; + //We will store these connection parameters for use elsewhere (ie, unit tests) + $this->parameters = $parameters; + $this->schemaManager->flushCache(); - // assumes that the path to dbname will always be provided - // this is only necessary if we're using a filesystem path, and not an in-memory database - if($file != ':memory:') { + // Ensure database name is set + if(empty($parameters['database'])) { + $parameters['database'] = 'database' . self::database_extension(); + } + $dbName = $parameters['database']; + if(!self::is_valid_database_name($dbName)) { + // If not using the correct file extension for database files then the + // results of SQLite3SchemaManager::databaseList will be unpredictable + $extension = self::database_extension(); + Deprecation::notice('3.2', "SQLite3Database now expects a database file with extension \"$extension\". Behaviour may be unpredictable otherwise."); + } + + // use the very lightspeed SQLite In-Memory feature for testing + if($this->getLivesInMemory()) { + $file = ':memory:'; + } else { + // Ensure path is given + if(empty($parameters['path'])) { + $parameters['path'] = ASSETS_PATH . '/.sqlitedb'; + } + + //assumes that the path to dbname will always be provided: $file = $parameters['path'] . '/' . $dbName; if(!file_exists($parameters['path'])) { SQLiteDatabaseConfigurationHelper::create_db_dir($parameters['path']); SQLiteDatabaseConfigurationHelper::secure_db_dir($parameters['path']); } } + + // 'path' and 'database' are merged into the full file path, which + // is the format that connectors such as PDOConnector expect + $parameters['filepath'] = $file; - $this->dbConn = new SQLite3($file, SQLITE3_OPEN_READWRITE | SQLITE3_OPEN_CREATE, $parameters['key']); - if(method_exists('SQLite3', 'busyTimeout')) $this->dbConn->busyTimeout(60000); - - $this->active = true; - $this->database = $dbName; - - if(!$this->dbConn) { - $this->databaseError("Couldn't connect to SQLite3 database"); - return false; + // Ensure that driver is available (required by PDO) + if(empty($parameters['driver'])) { + $parameters['driver'] = $this->getDatabaseServer(); } - - foreach(self::$default_pragma as $pragma => $value) $this->pragma($pragma, $value); - + + $this->connector->connect($parameters, true); + + foreach(self::$default_pragma as $pragma => $value) { + $this->setPragma($pragma, $value); + } + if(empty(self::$default_pragma['locking_mode'])) { - self::$default_pragma['locking_mode'] = $this->pragma('locking_mode'); + self::$default_pragma['locking_mode'] = $this->getPragma('locking_mode'); } - - return true; } /** - * Not implemented, needed for PDO + * Retrieve parameters used to connect to this SQLLite database + * + * @return array */ - public function getConnect($parameters) { - return null; + public function getParameters() { + return $this->parameters; + } + + public function getLivesInMemory() { + return isset($this->parameters['path']) && $this->parameters['path'] === ':memory:'; } - /** - * Returns true if this database supports collations - * TODO: get rid of this? - * @return boolean - */ public function supportsCollations() { return true; } @@ -126,745 +159,63 @@ class SQLite3Database extends SS_Database { return false; } - /** - * Get the version of SQLite3. - * @return float - */ - public function getVersion() { - return $this->query("SELECT sqlite_version()")->value(); - } - /** * Execute PRAGMA commands. - * works as getter and setter for connection params - * @param String pragma name - * @param String optional value to set - * @return String the pragma value - */ - protected function pragma($pragma, $value = null) { - if(strlen($value)) { - $this->query("PRAGMA $pragma = $value"); - } else { - $value = $this->query("PRAGMA $pragma")->value(); - } - - return $value; - } - /** - * Get the database server, namely SQLite3. - * @return string - */ - public function getDatabaseServer() { - return "SQLite3"; - } - - public function query($sql, $errorLevel = E_USER_ERROR) { - - if(isset($_REQUEST['previewwrite']) && in_array(strtolower(substr($sql,0,strpos($sql,' '))), array('insert','update','delete','replace'))) { - Debug::message("Will execute: $sql"); - return; - } - - if(isset($_REQUEST['showqueries'])) { - $starttime = microtime(true); - } - - @$handle = $this->dbConn->query($sql); - - if(isset($_REQUEST['showqueries'])) { - $endtime = round(microtime(true) - $starttime,4); - Debug::message("\n$sql\n{$endtime}ms\n", false); - } - - DB::$lastQuery=$handle; - - if(!$handle) { - $this->databaseError("Couldn't run query: $sql | " . $this->dbConn->lastErrorMsg(), $errorLevel); - } - - return new SQLite3Query($this, $handle); - } - - public function getGeneratedID($table) { - return $this->dbConn->lastInsertRowID(); - } - - /** - * OBSOLETE: Get the ID for the next new record for the table. * - * @var string $table The name od the table. - * @return int + * @param string pragma name + * @param string value to set */ - public function getNextID($table) { - user_error('getNextID is OBSOLETE (and will no longer work properly)', E_USER_WARNING); - $result = $this->query("SELECT MAX(ID)+1 FROM \"$table\"")->value(); - return $result ? $result : 1; - } - - public function isActive() { - return $this->active ? true : false; - } - - /* - * This will create a database based on whatever is in the $this->database value - * So you need to have called $this->selectDatabase() first, or used the __construct method - */ - public function createDatabase() { - - $this->dbConn = null; - $fullpath = $this->parameters['path'] . '/' . $this->database; - if(is_writable($fullpath)) unlink($fullpath); - - $this->connectDatabase(); - + public function setPragma($pragma, $value) { + $this->query("PRAGMA $pragma = $value"); } /** - * Drop the database that this object is currently connected to. - * Use with caution. + * Gets pragma value. + * + * @param string pragma name + * @return string the pragma value */ - public function dropDatabase() { - //First, we need to switch back to the original database so we can drop the current one - $this->dbConn = null; - $db_to_drop=$this->database; - $this->selectDatabase($this->database_original); - $this->connectDatabase(); - - $fullpath = $this->parameters['path'] . '/' . $db_to_drop; - if(is_writable($fullpath)) unlink($fullpath); + public function getPragma($pragma) { + return $this->query("PRAGMA $pragma")->value(); } - /** - * Returns the name of the currently selected database - */ - public function currentDatabase() { - return $this->database; + public function getDatabaseServer() { + return "sqlite"; } - /** - * Switches to the given database. - * If the database doesn't exist, you should call createDatabase() after calling selectDatabase() - */ - public function selectDatabase($dbname) { - $this->database=$dbname; - - $this->tableList = $this->fieldList = $this->indexList = null; + public function selectDatabase($name, $create = false, $errorLevel = E_USER_ERROR) { + if (!$this->schemaManager->databaseExists($name)) { + // Check DB creation permisson + if (!$create) { + if ($errorLevel !== false) { + user_error("Attempted to connect to non-existing database \"$name\"", $errorLevel); + } + // Unselect database + $this->connector->unloadDatabase(); + return false; + } + $this->schemaManager->createDatabase($name); + } + // Reconnect using the existing parameters + $parameters = $this->parameters; + $parameters['database'] = $name; + $this->connect($parameters); return true; } - - /** - * Returns true if the named database exists. - */ - public function databaseExists($name) { - $SQL_name=Convert::raw2sql($name); - $result=$this->query("PRAGMA database_list"); - foreach($result as $db) if($db['name'] == 'main' && preg_match('/\/' . $name . '/', $db['file'])) return true; - if(file_exists($this->parameters['path'] . '/' . $name)) return true; - return false; - } - - function beginSchemaUpdate() { - $this->pragma('locking_mode', 'EXCLUSIVE'); - $this->checkAndRepairTable(); - // if($this->TableExists('SQLiteEnums')) $this->query("DELETE FROM SQLiteEnums"); - $this->checkAndRepairTable(); - parent::beginSchemaUpdate(); - } - - function endSchemaUpdate() { - parent::endSchemaUpdate(); - $this->pragma('locking_mode', self::$default_pragma['locking_mode']); - } - - public function clearTable($table) { - if($table != 'SQLiteEnums') $this->dbConn->query("DELETE FROM \"$table\""); - } - - public function createTable($table, $fields = null, $indexes = null, $options = null, $advancedOptions = null) { - - if(!isset($fields['ID'])) $fields['ID'] = $this->IdColumn(); - - $fieldSchemata = array(); - if($fields) foreach($fields as $k => $v) { - $fieldSchemata[] = "\"$k\" $v"; - } - $fieldSchemas = implode(",\n",$fieldSchemata); - - // Switch to "CREATE TEMPORARY TABLE" for temporary tables - $temporary = empty($options['temporary']) ? "" : "TEMPORARY"; - $this->query("CREATE $temporary TABLE \"$table\" ( - $fieldSchemas - )"); - - if($indexes) { - foreach($indexes as $indexName => $indexDetails) { - $this->createIndex($table, $indexName, $indexDetails); - } - } - - return $table; - } - - /** - * Alter a table's schema. - * @param $table The name of the table to alter - * @param $newFields New fields, a map of field name => field schema - * @param $newIndexes New indexes, a map of index name => index type - * @param $alteredFields Updated fields, a map of field name => field schema - * @param $alteredIndexes Updated indexes, a map of index name => index type - */ - public function alterTable($tableName, $newFields = null, $newIndexes = null, $alteredFields = null, $alteredIndexes = null, $alteredOptions = null, $advancedOptions = null) { - - if($newFields) foreach($newFields as $fieldName => $fieldSpec) $this->createField($tableName, $fieldName, $fieldSpec); - - if($alteredFields) foreach($alteredFields as $fieldName => $fieldSpec) $this->alterField($tableName, $fieldName, $fieldSpec); - - if($newIndexes) foreach($newIndexes as $indexName => $indexSpec) $this->createIndex($tableName, $indexName, $indexSpec); - - if($alteredIndexes) foreach($alteredIndexes as $indexName => $indexSpec) $this->alterIndex($tableName, $indexName, $indexSpec); - - } - - public function renameTable($oldTableName, $newTableName) { - - $this->query("ALTER TABLE \"$oldTableName\" RENAME TO \"$newTableName\""); - - } - - protected static $checked_and_repaired = false; - - /** - * Repairs and reindexes the table. This might take a long time on a very large table. - * @var string $tableName The name of the table. - * @return boolean Return true if the table has integrity after the method is complete. - */ - public function checkAndRepairTable($tableName = null) { - $ok = true; - - if(!SapphireTest::using_temp_db() && !self::$checked_and_repaired) { - $this->alterationMessage("Checking database integrity","repaired"); - if($msgs = $this->query('PRAGMA integrity_check')) foreach($msgs as $msg) if($msg['integrity_check'] != 'ok') { Debug::show($msg['integrity_check']); $ok = false; } - if(self::$vacuum) { - $this->query('VACUUM', E_USER_NOTICE); - if($this instanceof SQLitePDODatabase) { - $msg = $this->dbConn->errorInfo(); - $msg = isset($msg[2]) ? $msg[2] : 'no errors'; - } else { - $msg = $this->dbConn->lastErrorMsg(); - } - if(preg_match('/authoriz/', $msg)) { - $this->alterationMessage('VACUUM | ' . $msg, "error"); - } else { - $this->alterationMessage("VACUUMing", "repaired"); - } - } - self::$checked_and_repaired = true; - } - - return $ok; - } - - public function createField($tableName, $fieldName, $fieldSpec) { - $this->query("ALTER TABLE \"$tableName\" ADD \"$fieldName\" $fieldSpec"); - } - - /** - * Change the database type of the given field. - * @param string $tableName The name of the tbale the field is in. - * @param string $fieldName The name of the field to change. - * @param string $fieldSpec The new field specification - */ - public function alterField($tableName, $fieldName, $fieldSpec) { - - $oldFieldList = $this->fieldList($tableName); - $fieldNameList = '"' . implode('","', array_keys($oldFieldList)) . '"'; - - if(!empty($_REQUEST['avoidConflict']) && Director::isDev()) $fieldSpec = preg_replace('/\snot null\s/i', ' NOT NULL ON CONFLICT REPLACE ', $fieldSpec); - - if(array_key_exists($fieldName, $oldFieldList)) { - - $oldCols = array(); - - foreach($oldFieldList as $name => $spec) { - $newColsSpec[] = "\"$name\" " . ($name == $fieldName ? $fieldSpec : $spec); - } - - $queries = array( - "BEGIN TRANSACTION", - "CREATE TABLE \"{$tableName}_alterfield_{$fieldName}\"(" . implode(',', $newColsSpec) . ")", - "INSERT INTO \"{$tableName}_alterfield_{$fieldName}\" SELECT {$fieldNameList} FROM \"$tableName\"", - "DROP TABLE \"$tableName\"", - "ALTER TABLE \"{$tableName}_alterfield_{$fieldName}\" RENAME TO \"$tableName\"", - "COMMIT" - ); - - $indexList = $this->indexList($tableName); - foreach($queries as $query) $this->query($query.';'); - - foreach($indexList as $indexName => $indexSpec) $this->createIndex($tableName, $indexName, $indexSpec); - - } - - } - - /** - * Change the database column name of the given field. - * - * @param string $tableName The name of the tbale the field is in. - * @param string $oldName The name of the field to change. - * @param string $newName The new name of the field - */ - public function renameField($tableName, $oldName, $newName) { - $oldFieldList = $this->fieldList($tableName); - $oldCols = array(); - - if(array_key_exists($oldName, $oldFieldList)) { - foreach($oldFieldList as $name => $spec) { - $oldCols[] = "\"$name\"" . (($name == $oldName) ? " AS $newName" : ''); - $newCols[] = "\"". (($name == $oldName) ? $newName : $name). "\""; - $newColsSpec[] = "\"" . (($name == $oldName) ? $newName : $name) . "\" $spec"; - } - - // SQLite doesn't support direct renames through ALTER TABLE - $queries = array( - "BEGIN TRANSACTION", - "CREATE TABLE \"{$tableName}_renamefield_{$oldName}\" (" . implode(',', $newColsSpec) . ")", - "INSERT INTO \"{$tableName}_renamefield_{$oldName}\" SELECT " . implode(',', $oldCols) . " FROM \"$tableName\"", - "DROP TABLE \"$tableName\"", - "ALTER TABLE \"{$tableName}_renamefield_{$oldName}\" RENAME TO \"$tableName\"", - "COMMIT" - ); - - // Remember original indexes - $oldIndexList = $this->indexList($tableName); - - // Then alter the table column - foreach($queries as $query) $this->query($query.';'); - - // Recreate the indexes - foreach($oldIndexList as $indexName => $indexSpec) { - $renamedIndexSpec = array(); - foreach(explode(',', $indexSpec) as $col) { - $col = trim($col, '"'); // remove quotes - $renamedIndexSpec[] = ($col == $oldName) ? $newName : $col; - } - $this->createIndex($tableName, $indexName, implode(',', $renamedIndexSpec)); - } - } - } - - public function fieldList($table) { - $sqlCreate = DB::query('SELECT sql FROM sqlite_master WHERE type = "table" AND name = "' . $table . '"')->record(); - $fieldList = array(); - - if($sqlCreate && $sqlCreate['sql']) { - preg_match('/^[\s]*CREATE[\s]+TABLE[\s]+[\'"]?[a-zA-Z0-9_\\\]+[\'"]?[\s]*\((.+)\)[\s]*$/ims', $sqlCreate['sql'], $matches); - $fields = isset($matches[1]) ? preg_split('/,(?=(?:[^\'"]*$)|(?:[^\'"]*[\'"][^\'"]*[\'"][^\'"]*)*$)/x', $matches[1]) : array(); - foreach($fields as $field) { - $details = preg_split('/\s/', trim($field)); - $name = array_shift($details); - $name = str_replace('"', '', trim($name)); - $fieldList[$name] = implode(' ', $details); - } - } - - return $fieldList; - } - - /** - * Create an index on a table. - * @param string $tableName The name of the table. - * @param string $indexName The name of the index. - * @param string $indexSpec The specification of the index, see Database::requireIndex() for more details. - */ - public function createIndex($tableName, $indexName, $indexSpec) { - $spec = $this->convertIndexSpec($indexSpec, $indexName); - if(!preg_match('/".+"/', $indexName)) $indexName = "\"$indexName\""; - - $this->query("CREATE INDEX IF NOT EXISTS $indexName ON \"$tableName\" ($spec)"); - - } - - /* - * This takes the index spec which has been provided by a class (ie static $indexes = blah blah) - * and turns it into a proper string. - * Some indexes may be arrays, such as fulltext and unique indexes, and this allows database-specific - * arrays to be created. - */ - public function convertIndexSpec($indexSpec, $indexName = null) { - if(is_array($indexSpec)) { - $indexSpec = $indexSpec['value']; - } else if(is_numeric($indexSpec)) { - $indexSpec = $indexName; - } - - if(preg_match('/\((.+)\)/', $indexSpec, $matches)) { - $indexSpec = $matches[1]; - } - - return preg_replace('/\s/', '', $indexSpec); - } - - /** - * prefix indexname with uppercase tablename if not yet done, in order to avoid ambiguity - */ - function getDbSqlDefinition($tableName, $indexName, $indexSpec) { - return "\"$tableName.$indexName\""; - } - - /** - * Alter an index on a table. - * @param string $tableName The name of the table. - * @param string $indexName The name of the index. - * @param string $indexSpec The specification of the index, see Database::requireIndex() for more details. - */ - public function alterIndex($tableName, $indexName, $indexSpec) { - $this->createIndex($tableName, $indexName, $indexSpec); - } - - /** - * Return the list of indexes in a table. - * @param string $table The table name. - * @return array - */ - public function indexList($table) { - $indexList = array(); - foreach(DB::query('PRAGMA index_list("' . $table . '")') as $index) { - $list = array(); - foreach(DB::query('PRAGMA index_info("' . $index["name"] . '")') as $details) $list[] = $details['name']; - $indexList[$index["name"]] = implode(',', $list); - } - foreach($indexList as $name => $val) { - // Normalize quoting to avoid false positives when checking for index changes - // during schema generation - $valParts = preg_split('/\s*,\s*/', $val); - foreach($valParts as $i => $valPart) { - $valParts[$i] = preg_replace('/^"?(.*)"?$/', '$1', $valPart); - } - - $indexList[$name] = '"' . implode('","', $valParts) . '"'; - } - - return $indexList; - } - - /** - * Returns a list of all the tables in the database. - * Table names will all be in lowercase. - * @return array - */ - public function tableList() { - $tables = array(); - foreach($this->query('SELECT name FROM sqlite_master WHERE type = "table"') as $record) { - //$table = strtolower(reset($record)); - $table = reset($record); - $tables[strtolower($table)] = $table; - } - - //Return an empty array if there's nothing in this database - return isset($tables) ? $tables : Array(); - } - - function TableExists($tableName){ - - $result=$this->query('SELECT name FROM sqlite_master WHERE type = "table" AND name="' . $tableName . '"')->first(); - - if($result) - return true; - else - return false; - - } - - /** - * Return the number of rows affected by the previous operation. - * @return int - */ - public function affectedRows() { - return $this->dbConn->changes(); - } - - /** - * Return a boolean type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function boolean($values){ - - return 'BOOL NOT NULL DEFAULT ' . (isset($values['default']) ? (int)$values['default'] : 0); - - } - - /** - * Return a date type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function date($values){ - - return "TEXT"; - - } - - /** - * Return a decimal type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function decimal($values, $asDbValue=false){ - - $default = isset($values['default']) && is_numeric($values['default']) ? $values['default'] : 0; - return "NUMERIC NOT NULL DEFAULT " . $default; - - } - - /** - * Return a enum type-formatted string - * - * enumus are not supported. as a workaround to store allowed values we creates an additional table - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - protected $enum_map = array(); - - public function enum($values){ - $tablefield = $values['table'] . '.' . $values['name']; - if(empty($this->enum_map)) $this->query("CREATE TABLE IF NOT EXISTS \"SQLiteEnums\" (\"TableColumn\" TEXT PRIMARY KEY, \"EnumList\" TEXT)"); - if(empty($this->enum_map[$tablefield]) || $this->enum_map[$tablefield] != implode(',', $values['enums'])) { - $this->query("REPLACE INTO SQLiteEnums (TableColumn, EnumList) VALUES (\"{$tablefield}\", \"" . implode(',', $values['enums']) . "\")"); - $this->enum_map[$tablefield] = implode(',', $values['enums']); - } - return "TEXT DEFAULT '{$values['default']}'"; - } - - /** - * Return a set type-formatted string - * This type doesn't exist in SQLite as well - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function set($values) { - $tablefield = $values['table'] . '.' . $values['name']; - if(empty($this->enum_map)) $this->query("CREATE TABLE IF NOT EXISTS SQLiteEnums (TableColumn TEXT PRIMARY KEY, EnumList TEXT)"); - if(empty($this->enum_map[$tablefield]) || $this->enum_map[$tablefield] != implode(',', $values['enums'])) { - $this->query("REPLACE INTO SQLiteEnums (TableColumn, EnumList) VALUES (\"{$tablefield}\", \"" . implode(',', $values['enums']) . "\")"); - $this->enum_map[$tablefield] = implode(',', $values['enums']); - } - $default = ''; - if(!empty($values['default'])) { - $default = str_replace(array('"',"'","\\","\0"), "", $values['default']); - $default = " DEFAULT '$default'"; - } - return 'TEXT' . $default; - } - - /** - * Return a float type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function float($values, $asDbValue=false){ - - return "REAL"; - - } - - /** - * Return a Double type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function Double($values, $asDbValue=false){ - - return "REAL"; - - } - - /** - * Return a int type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function int($values, $asDbValue=false){ - - return "INTEGER({$values['precision']}) " . strtoupper($values['null']) . " DEFAULT " . (int)$values['default']; - - } - - /** - * Return a datetime type-formatted string - * For SQLite3, we simply return the word 'TEXT', no other parameters are necessary - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function ss_datetime($values, $asDbValue=false){ - - return "DATETIME"; - - } - - /** - * Return a text type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function text($values, $asDbValue=false){ - - return 'TEXT'; - - } - - /** - * Return a time type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function time($values){ - - return "TEXT"; - - } - - /** - * Return a varchar type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function varchar($values, $asDbValue=false){ - return "VARCHAR({$values['precision']}) COLLATE NOCASE"; - } - - /* - * Return a 4 digit numeric type. MySQL has a proprietary 'Year' type. - * For SQLite3 we use TEXT - */ - public function year($values, $asDbValue=false){ - - return "TEXT"; - - } - - function escape_character($escape=false){ - - if($escape) return "\\\""; else return "\""; - - } - - /** - * This returns the column which is the primary key for each table - * In SQLite3 it is INTEGER PRIMARY KEY AUTOINCREMENT - * SQLite3 does autoincrement ids even without the AUTOINCREMENT keyword, but the behaviour is signifficantly different - * - * @return string - */ - function IdColumn($asDbValue=false){ - return 'INTEGER PRIMARY KEY AUTOINCREMENT'; - } - - /** - * Returns true if this table exists - */ - function hasTable($tableName) { - $SQL_table = Convert::raw2sql($tableName); - return (bool)($this->query("SELECT name FROM sqlite_master WHERE type = \"table\" AND name = \"$tableName\"")->value()); - } - - /** - * Returns the SQL command to get all the tables in this database - */ - function allTablesSQL(){ - return 'SELECT name FROM sqlite_master WHERE type = "table"'; - } - - /** - * Return enum values for the given field - * @return array - */ - public function enumValuesForField($tableName, $fieldName) { - $classnameinfo = DB::query("SELECT EnumList FROM SQLiteEnums WHERE TableColumn = \"{$tableName}.{$fieldName}\"")->first(); - $output = array(); - if($classnameinfo) { - $output = explode(',', $classnameinfo['EnumList']); - } - return $output; - } - - /** - * Get the actual enum fields from the constraint value: - */ - protected function EnumValuesFromConstraint($constraint){ - $constraint=substr($constraint, strpos($constraint, 'ANY (ARRAY[')+11); - $constraint=substr($constraint, 0, -11); - $constraints=Array(); - $segments=explode(',', $constraint); - foreach($segments as $this_segment){ - $bits=preg_split('/ *:: */', $this_segment); - array_unshift($constraints, trim($bits[0], " '")); - } - - return $constraints; - } - - /* - * Returns the database-specific version of the now() function - */ function now(){ return "datetime('now', 'localtime')"; } - /* - * Returns the database-specific version of the random() function - */ function random(){ return 'random()'; } - /* - * This is a lookup table for data types. - * For instance, Postgres uses 'INT', while MySQL uses 'UNSIGNED' - * So this is a DB-specific list of equivalents. - */ - function dbDataType($type){ - $values=Array( - 'unsigned integer'=>'INT' - ); - - if(isset($values[$type])) - return $values[$type]; - else return ''; - } - - /* - * This will return text which has been escaped in a database-friendly manner - */ - function addslashes($value){ - return $this->dbConn->escapeString($value); - } - - /* - * This changes the index name depending on database requirements. - */ - function modifyIndex($index, $spec){ - return str_replace('"', '', $index); - } - /** * The core search engine configuration. - * @todo There is a fulltext search for SQLite making use of virtual tables, the fts3 extension and the MATCH operator + * @todo There is a fulltext search for SQLite making use of virtual tables, the fts3 extension and the + * MATCH operator * there are a few issues with fts: * - shared cached lock doesn't allow to create virtual tables on versions prior to 3.6.17 * - there must not be more than one MATCH operator per statement @@ -874,9 +225,10 @@ class SQLite3Database extends SS_Database { * @param string $keywords Keywords as a space separated string * @return object DataObjectSet of result pages */ - public function searchEngine($classesToSearch, $keywords, $start, $pageLength, $sortBy = "Relevance DESC", $extraFilter = "", $booleanSearch = false, $alternativeFileFilter = "", $invertedMatch = false) { - $fileFilter = ''; - $keywords = Convert::raw2sql(str_replace(array('*','+','-','"','\''),'',$keywords)); + public function searchEngine($classesToSearch, $keywords, $start, $pageLength, $sortBy = "Relevance DESC", + $extraFilter = "", $booleanSearch = false, $alternativeFileFilter = "", $invertedMatch = false + ) { + $keywords = $this->escapeString(str_replace(array('*','+','-','"','\''), '', $keywords)); $htmlEntityKeywords = htmlentities(utf8_decode($keywords)); $extraFilters = array('SiteTree' => '', 'File' => ''); @@ -892,7 +244,7 @@ class SQLite3Database extends SS_Database { $extraFilters['SiteTree'] .= ' AND ShowInSearch <> 0'; // File.ShowInSearch was added later, keep the database driver backwards compatible // by checking for its existence first - $fields = $this->fieldList('File'); + $fields = $this->getSchemaManager()->fieldList('File'); if(array_key_exists('ShowInSearch', $fields)) { $extraFilters['File'] .= " AND ShowInSearch <> 0"; } @@ -977,15 +329,17 @@ class SQLite3Database extends SS_Database { // Combine queries $querySQLs = array(); + $queryParameters = array(); $totalCount = 0; foreach($queries as $query) { - $querySQLs[] = $query->sql(); + $querySQLs[] = $query->sql($parameters); + $queryParameters = array_merge($queryParameters, $parameters); $totalCount += $query->unlimitedRowCount(); } $fullQuery = implode(" UNION ", $querySQLs) . " ORDER BY $sortBy LIMIT $limit"; // Get records - $records = DB::query($fullQuery); + $records = $this->preparedQuery($fullQuery, $queryParameters); foreach($records as $record) { $objects[] = new $record['ClassName']($record); @@ -1007,10 +361,7 @@ class SQLite3Database extends SS_Database { return version_compare($this->getVersion(), '3.6', '>='); } - /* - * This is a quick lookup to discover if the database supports particular extensions - */ - public function supportsExtensions($extensions=Array('partitions', 'tablespaces', 'clustering')){ + public function supportsExtensions($extensions = array('partitions', 'tablespaces', 'clustering')){ if(isset($extensions['partitions'])) return true; @@ -1022,79 +373,34 @@ class SQLite3Database extends SS_Database { return false; } - /** - * @deprecated 1.2 use transactionStart() (method required for 2.4.x) - */ - public function startTransaction($transaction_mode=false, $session_characteristics=false){ - $this->transactionStart($transaction_mode, $session_characteristics); + public function transactionStart($transaction_mode = false, $session_characteristics = false) { + $this->query('BEGIN'); } - /* - * Start a prepared transaction - */ - public function transactionStart($transaction_mode=false, $session_characteristics=false){ - DB::query('BEGIN'); + public function transactionSavepoint($savepoint) { + $this->query("SAVEPOINT \"$savepoint\""); } - /* - * Create a savepoint that you can jump back to if you encounter problems - */ - public function transactionSavepoint($savepoint){ - DB::query("SAVEPOINT \"$savepoint\""); - } - - /* - * Rollback or revert to a savepoint if your queries encounter problems - * If you encounter a problem at any point during a transaction, you may - * need to rollback that particular query, or return to a savepoint - */ - public function transactionRollback($savepoint=false){ + public function transactionRollback($savepoint = false){ if($savepoint) { - DB::query("ROLLBACK TO $savepoint;"); + $this->query("ROLLBACK TO $savepoint;"); } else { - DB::query('ROLLBACK;'); + $this->query('ROLLBACK;'); } } - /** - * @deprecated 1.2 use transactionEnd() (method required for 2.4.x) - */ - public function endTransaction(){ - $this->transactionEnd(); + public function transactionEnd($chain = false){ + $this->query('COMMIT;'); } - /* - * Commit everything inside this transaction so far - */ - public function transactionEnd(){ - DB::query('COMMIT;'); + public function clearTable($table) { + $this->query("DELETE FROM \"$table\""); } - /** - * - * This is a stub function. Postgres caches the fieldlist results. - * - * @param string $tableName - * - * @return boolean - */ - function clear_cached_fieldlist($tableName=false){ - return true; - } - - /** - * Generate a WHERE clause for text matching. - * - * @param String $field Quoted field name - * @param String $value Escaped search. Can include percentage wildcards. - * @param boolean $exact Exact matches or wildcard support. - * @param boolean $negate Negate the clause. - * @param boolean $caseSensitive Enforce case sensitivity if TRUE or FALSE. - * Stick with default collation if set to NULL. - * @return String SQL - */ - public function comparisonClause($field, $value, $exact = false, $negate = false, $caseSensitive = null) { + public function comparisonClause($field, $value, $exact = false, $negate = false, $caseSensitive = null, + $parameterised = false + ) { if($exact && !$caseSensitive) { $comp = ($negate) ? '!=' : '='; } else { @@ -1110,29 +416,18 @@ class SQLite3Database extends SS_Database { } if($negate) $comp = 'NOT ' . $comp; } - - return sprintf("%s %s '%s'", $field, $comp, $value); + + if($parameterised) { + return sprintf("%s %s ?", $field, $comp); + } else { + return sprintf("%s %s '%s'", $field, $comp, $value); + } } - /** - * Function to return an SQL datetime expression that can be used with SQLite3 - * used for querying a datetime in a certain format - * @param string $date to be formated, can be either 'now', literal datetime like '1973-10-14 10:30:00' or field name, e.g. '"SiteTree"."Created"' - * @param string $format to be used, supported specifiers: - * %Y = Year (four digits) - * %m = Month (01..12) - * %d = Day (01..31) - * %H = Hour (00..23) - * %i = Minutes (00..59) - * %s = Seconds (00..59) - * %U = unix timestamp, can only be used on it's own - * @return string SQL datetime expression to query for a formatted datetime - */ function formattedDatetimeClause($date, $format) { - preg_match_all('/%(.)/', $format, $matches); foreach($matches[1] as $match) if(array_search($match, array('Y','m','d','H','i','s','U')) === false) user_error('formattedDatetimeClause(): unsupported format character %' . $match, E_USER_WARNING); - + $translate = array( '/%i/' => '%M', '/%s/' => '%S', @@ -1153,22 +448,7 @@ class SQLite3Database extends SS_Database { $modifier = empty($modifiers) ? '' : ", '" . implode("', '", $modifiers) . "'"; return "strftime('$format', $date$modifier)"; } - - /** - * Function to return an SQL datetime expression that can be used with SQLite3 - * used for querying a datetime addition - * @param string $date, can be either 'now', literal datetime like '1973-10-14 10:30:00' or field name, e.g. '"SiteTree"."Created"' - * @param string $interval to be added, use the format [sign][integer] [qualifier], e.g. -1 Day, +15 minutes, +1 YEAR - * supported qualifiers: - * - years - * - months - * - days - * - hours - * - minutes - * - seconds - * This includes the singular forms as well - * @return string SQL datetime expression to query for a datetime (YYYY-MM-DD hh:mm:ss) which is the result of the addition - */ + function datetimeIntervalClause($date, $interval) { $modifiers = array(); if($date == 'now') $modifiers[] = 'localtime'; @@ -1183,15 +463,7 @@ class SQLite3Database extends SS_Database { return "datetime($date$modifier, '$interval')"; } - /** - * Function to return an SQL datetime expression that can be used with SQLite3 - * used for querying a datetime substraction - * @param string $date1, can be either 'now', literal datetime like '1973-10-14 10:30:00' or field name, e.g. '"SiteTree"."Created"' - * @param string $date2 to be substracted of $date1, can be either 'now', literal datetime like '1973-10-14 10:30:00' or field name, e.g. '"SiteTree"."Created"' - * @return string SQL datetime expression to query for the interval between $date1 and $date2 in seconds which is the result of the substraction - */ function datetimeDifferenceClause($date1, $date2) { - $modifiers1 = array(); $modifiers2 = array(); @@ -1216,61 +488,3 @@ class SQLite3Database extends SS_Database { return "strftime('%s', $date1$modifier1) - strftime('%s', $date2$modifier2)"; } } - -/** - * A result-set from a SQLite3 database. - * @package SQLite3Database - */ -class SQLite3Query extends SS_Query { - - /** - * The SQLite3Database object that created this result set. - * @var SQLite3Database - */ - protected $database; - - /** - * The internal sqlite3 handle that points to the result set. - * @var resource - */ - protected $handle; - - /** - * Hook the result-set given into a Query class, suitable for use by framework. - * @param database The database object that created this query. - * @param handle the internal sqlite3 handle that is points to the resultset. - */ - public function __construct(SQLite3Database $database, $handle) { - $this->database = $database; - $this->handle = $handle; - } - - public function __destruct() { - if($this->handle) $this->handle->finalize(); - } - - public function seek($row) { - $this->handle->reset(); - $i=0; - while($i < $row && $row = @$this->handle->fetchArray()) $i++; - return true; - } - - /** - * @todo This looks terrible but there is no SQLite3::get_num_rows() implementation - */ - public function numRecords() { - $c=0; - while($this->handle->fetchArray()) $c++; - $this->handle->reset(); - return $c; - } - - public function nextRecord() { - if($data = $this->handle->fetchArray(SQLITE3_ASSOC)) { - return $data; - } else { - return false; - } - } -} diff --git a/code/SQLite3Query.php b/code/SQLite3Query.php new file mode 100644 index 0000000..ee6706e --- /dev/null +++ b/code/SQLite3Query.php @@ -0,0 +1,62 @@ +database = $database; + $this->handle = $handle; + } + + public function __destruct() { + if($this->handle) $this->handle->finalize(); + } + + public function seek($row) { + $this->handle->reset(); + $i=0; + while($i < $row && $row = @$this->handle->fetchArray()) $i++; + return true; + } + + /** + * @todo This looks terrible but there is no SQLite3::get_num_rows() implementation + */ + public function numRecords() { + $c=0; + while($this->handle->fetchArray()) $c++; + $this->handle->reset(); + return $c; + } + + public function nextRecord() { + if($data = $this->handle->fetchArray(SQLITE3_ASSOC)) { + return $data; + } else { + return false; + } + } +} diff --git a/code/SQLite3QueryBuilder.php b/code/SQLite3QueryBuilder.php new file mode 100644 index 0000000..f908787 --- /dev/null +++ b/code/SQLite3QueryBuilder.php @@ -0,0 +1,49 @@ +getSeparator(); + $into = $query->getInto(); + + // Column identifiers + $columns = $query->getColumns(); + + // Build all rows + $rowParts = array(); + foreach($query->getRows() as $row) { + // Build all columns in this row + $assignments = $row->getAssignments(); + // Join SET components together, considering parameters + $parts = array(); + foreach($columns as $column) { + // Check if this column has a value for this row + if(isset($assignments[$column])) { + // Assigment is a single item array, expand with a loop here + foreach($assignments[$column] as $assignmentSQL => $assignmentParameters) { + $parts[] = $assignmentSQL; + $parameters = array_merge($parameters, $assignmentParameters); + break; + } + } else { + // This row is missing a value for a column used by another row + $parts[] = '?'; + $parameters[] = null; + } + } + $rowParts[] = implode(', ', $parts); + } + $columnSQL = implode(', ', $columns); + $sql = "INSERT INTO {$into}{$nl}($columnSQL){$nl}SELECT " . implode("{$nl}UNION ALL SELECT ", $rowParts); + + return $sql; + } +} diff --git a/code/SQLite3SchemaManager.php b/code/SQLite3SchemaManager.php new file mode 100644 index 0000000..2d085d4 --- /dev/null +++ b/code/SQLite3SchemaManager.php @@ -0,0 +1,605 @@ +dropDatabase($name); + } + + public function dropDatabase($name) { + // No need to delete database files if operating purely within memory + if($this->database->getLivesInMemory()) return; + + // If using file based database ensure any existing file is removed + $parameters = $this->database->getParameters(); + $fullpath = $parameters['path'] . '/' . $name; + if(is_writable($fullpath)) unlink($fullpath); + } + + function databaseList() { + $parameters = $this->database->getParameters(); + + // If in-memory use the current database name only + if($this->database->getLivesInMemory()) { + return array($parameters['database']); + } + + // If using file based database enumerate files in the database directory + $directory = $parameters['path']; + $files = scandir($directory); + + // Filter each file in this directory + $databases = array(); + if($files !== false) foreach($files as $file) { + + // Filter non-files + if(!is_file("$directory/$file")) continue; + + // Filter those with correct extension + if(!SQLite3Database::is_valid_database_name($file)) continue; + + $databases[] = $file; + } + return $databases; + } + + public function databaseExists($name) { + $databases = $this->databaseList(); + return in_array($name, $databases); + } + + /** + * Empties any cached enum values + */ + public function flushCache() { + $this->enum_map = array(); + } + + function schemaUpdate($callback) { + // Set locking mode + $this->database->setPragma('locking_mode', 'EXCLUSIVE'); + $this->checkAndRepairTable(); + $this->flushCache(); + + // Initiate schema update + $error = null; + try { + parent::schemaUpdate($callback); + } catch(Exception $ex) { + $error = $ex; + } + + // Revert locking mode + $this->database->setPragma('locking_mode', SQLite3Database::$default_pragma['locking_mode']); + + if($error) throw $error; + } + + /** + * Empty a specific table + * + * @param string $table + */ + public function clearTable($table) { + if($table != 'SQLiteEnums') $this->dbConn->query("DELETE FROM \"$table\""); + } + + public function createTable($table, $fields = null, $indexes = null, $options = null, $advancedOptions = null) { + if(!isset($fields['ID'])) $fields['ID'] = $this->IdColumn(); + + $fieldSchemata = array(); + if($fields) foreach($fields as $k => $v) { + $fieldSchemata[] = "\"$k\" $v"; + } + $fieldSchemas = implode(",\n", $fieldSchemata); + + // Switch to "CREATE TEMPORARY TABLE" for temporary tables + $temporary = empty($options['temporary']) ? "" : "TEMPORARY"; + $this->query("CREATE $temporary TABLE \"$table\" ( + $fieldSchemas + )"); + + if($indexes) { + foreach($indexes as $indexName => $indexDetails) { + $this->createIndex($table, $indexName, $indexDetails); + } + } + + return $table; + } + + public function alterTable($tableName, $newFields = null, $newIndexes = null, $alteredFields = null, + $alteredIndexes = null, $alteredOptions = null, $advancedOptions = null + ) { + if($newFields) foreach($newFields as $fieldName => $fieldSpec) { + $this->createField($tableName, $fieldName, $fieldSpec); + } + + if($alteredFields) foreach($alteredFields as $fieldName => $fieldSpec) { + $this->alterField($tableName, $fieldName, $fieldSpec); + } + + if($newIndexes) foreach($newIndexes as $indexName => $indexSpec) { + $this->createIndex($tableName, $indexName, $indexSpec); + } + + if($alteredIndexes) foreach($alteredIndexes as $indexName => $indexSpec) { + $this->alterIndex($tableName, $indexName, $indexSpec); + } + } + + public function renameTable($oldTableName, $newTableName) { + $this->query("ALTER TABLE \"$oldTableName\" RENAME TO \"$newTableName\""); + } + + public function checkAndRepairTable($tableName = null) { + $ok = true; + + if(!SapphireTest::using_temp_db() && !self::$checked_and_repaired) { + $this->alterationMessage("Checking database integrity", "repaired"); + + // Check for any tables with failed integrity + if($messages = $this->query('PRAGMA integrity_check')) { + foreach($messages as $message) if($message['integrity_check'] != 'ok') { + Debug::show($message['integrity_check']); + $ok = false; + } + } + + // If enabled vacuum (clean and rebuild) the database + if(self::$vacuum) { + $this->query('VACUUM', E_USER_NOTICE); + $message = $this->database->getConnector()->getLastError(); + if(preg_match('/authoriz/', $message)) { + $this->alterationMessage("VACUUM | $message", "error"); + } else { + $this->alterationMessage("VACUUMing", "repaired"); + } + } + self::$checked_and_repaired = true; + } + + return $ok; + } + + public function createField($table, $field, $spec) { + $this->query("ALTER TABLE \"$table\" ADD \"$field\" $spec"); + } + + /** + * Change the database type of the given field. + * @param string $tableName The name of the tbale the field is in. + * @param string $fieldName The name of the field to change. + * @param string $fieldSpec The new field specification + */ + public function alterField($tableName, $fieldName, $fieldSpec) { + $oldFieldList = $this->fieldList($tableName); + $fieldNameList = '"' . implode('","', array_keys($oldFieldList)) . '"'; + + if(!empty($_REQUEST['avoidConflict']) && Director::isDev()) { + $fieldSpec = preg_replace('/\snot null\s/i', ' NOT NULL ON CONFLICT REPLACE ', $fieldSpec); + } + + // Skip non-existing columns + if(!array_key_exists($fieldName, $oldFieldList)) return; + + // Update field spec + $newColsSpec = array(); + foreach($oldFieldList as $name => $oldSpec) { + $newColsSpec[] = "\"$name\" " . ($name == $fieldName ? $fieldSpec : $oldSpec); + } + + $queries = array( + "BEGIN TRANSACTION", + "CREATE TABLE \"{$tableName}_alterfield_{$fieldName}\"(" . implode(',', $newColsSpec) . ")", + "INSERT INTO \"{$tableName}_alterfield_{$fieldName}\" SELECT {$fieldNameList} FROM \"$tableName\"", + "DROP TABLE \"$tableName\"", + "ALTER TABLE \"{$tableName}_alterfield_{$fieldName}\" RENAME TO \"$tableName\"", + "COMMIT" + ); + + // Remember original indexes + $indexList = $this->indexList($tableName); + + // Then alter the table column + foreach($queries as $query) $this->query($query.';'); + + // Recreate the indexes + foreach($indexList as $indexName => $indexSpec) { + $this->createIndex($tableName, $indexName, $indexSpec); + } + } + + public function renameField($tableName, $oldName, $newName) { + $oldFieldList = $this->fieldList($tableName); + + // Skip non-existing columns + if(!array_key_exists($oldName, $oldFieldList)) return; + + // Determine column mappings + $oldCols = array(); + $newColsSpec = array(); + foreach($oldFieldList as $name => $spec) { + $oldCols[] = "\"$name\"" . (($name == $oldName) ? " AS $newName" : ''); + $newColsSpec[] = "\"" . (($name == $oldName) ? $newName : $name) . "\" $spec"; + } + + // SQLite doesn't support direct renames through ALTER TABLE + $queries = array( + "BEGIN TRANSACTION", + "CREATE TABLE \"{$tableName}_renamefield_{$oldName}\" (" . implode(',', $newColsSpec) . ")", + "INSERT INTO \"{$tableName}_renamefield_{$oldName}\" SELECT " . implode(',', $oldCols) . " FROM \"$tableName\"", + "DROP TABLE \"$tableName\"", + "ALTER TABLE \"{$tableName}_renamefield_{$oldName}\" RENAME TO \"$tableName\"", + "COMMIT" + ); + + // Remember original indexes + $oldIndexList = $this->indexList($tableName); + + // Then alter the table column + foreach($queries as $query) $this->query($query.';'); + + // Recreate the indexes + foreach($oldIndexList as $indexName => $indexSpec) { + // Rename columns to new columns + $indexSpec['value'] = preg_replace("/\"$oldName\"/i", "\"$newName\"", $indexSpec['value']); + $this->createIndex($tableName, $indexName, $indexSpec); + } + } + + public function fieldList($table) { + $sqlCreate = $this->preparedQuery( + 'SELECT sql FROM sqlite_master WHERE type = ? AND name = ?', + array('table', $table) + )->record(); + + $fieldList = array(); + if($sqlCreate && $sqlCreate['sql']) { + preg_match('/^[\s]*CREATE[\s]+TABLE[\s]+[\'"]?[a-zA-Z0-9_\\\]+[\'"]?[\s]*\((.+)\)[\s]*$/ims', + $sqlCreate['sql'], $matches + ); + $fields = isset($matches[1]) + ? preg_split('/,(?=(?:[^\'"]*$)|(?:[^\'"]*[\'"][^\'"]*[\'"][^\'"]*)*$)/x', $matches[1]) + : array(); + foreach($fields as $field) { + $details = preg_split('/\s/', trim($field)); + $name = array_shift($details); + $name = str_replace('"', '', trim($name)); + $fieldList[$name] = implode(' ', $details); + } + } + return $fieldList; + } + + /** + * Create an index on a table. + * + * @param string $tableName The name of the table. + * @param string $indexName The name of the index. + * @param array $indexSpec The specification of the index, see Database::requireIndex() for more details. + */ + public function createIndex($tableName, $indexName, $indexSpec) { + $parsedSpec = $this->parseIndexSpec($indexName, $indexSpec); + $sqliteName = $this->buildSQLiteIndexName($tableName, $indexName); + $columns = $parsedSpec['value']; + $unique = ($parsedSpec['type'] == 'unique') ? 'UNIQUE' : ''; + $this->query("CREATE $unique INDEX IF NOT EXISTS \"$sqliteName\" ON \"$tableName\" ($columns)"); + } + + public function alterIndex($tableName, $indexName, $indexSpec) { + // Drop existing index + $sqliteName = $this->buildSQLiteIndexName($tableName, $indexName); + $this->query("DROP INDEX IF EXISTS \"$sqliteName\""); + + // Create the index + $this->createIndex($tableName, $indexName, $indexSpec); + } + + /** + * Builds the internal SQLLite index name given the silverstripe table and index name. + * + * The name is built using the table and index name in order to prevent name collisions + * between indexes of the same name across multiple tables + * + * @param string $tableName + * @param string $indexName + * @return string The SQLite3 name of the index + */ + protected function buildSQLiteIndexName($tableName, $indexName) { + return "{$tableName}_{$indexName}"; + } + + protected function parseIndexSpec($name, $spec) { + $spec = parent::parseIndexSpec($name, $spec); + + // Only allow index / unique index types + if(!in_array($spec['type'], array('index', 'unique'))) { + $spec['type'] = 'index'; + } + + return $spec; + } + + public function indexKey($table, $index, $spec) { + return $this->buildSQLiteIndexName($table, $index); + } + + public function indexList($table) { + $indexList = array(); + + // Enumerate each index and related fields + foreach($this->query("PRAGMA index_list(\"$table\")") as $index) { + + // The SQLite internal index name, not the actual Silverstripe name + $indexName = $index["name"]; + $indexType = $index['unique'] ? 'unique' : 'index'; + + // Determine a clean list of column names within this index + $list = array(); + foreach($this->query("PRAGMA index_info(\"$indexName\")") as $details) { + $list[] = preg_replace('/^"?(.*)"?$/', '$1', $details['name']); + } + + // Safely encode this spec + $indexList[$indexName] = $this->parseIndexSpec($indexName, array( + 'name' => $indexName, + 'value' => $this->implodeColumnList($list), + 'type' => $indexType + )); + } + + return $indexList; + } + + public function tableList() { + $tables = array(); + $result = $this->preparedQuery('SELECT name FROM sqlite_master WHERE type = ?', array('table')); + foreach($result as $record) { + $table = reset($record); + $tables[strtolower($table)] = $table; + } + return $tables; + } + + /** + * Return a boolean type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function boolean($values) { + $default = empty($values['default']) ? 0 : (int)$values['default']; + return "BOOL NOT NULL DEFAULT $default"; + } + + /** + * Return a date type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function date($values){ + return "TEXT"; + } + + /** + * Return a decimal type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function decimal($values, $asDbValue = false) { + $default = isset($values['default']) && is_numeric($values['default']) ? $values['default'] : 0; + return "NUMERIC NOT NULL DEFAULT $default"; + } + + /** + * Cached list of enum values indexed by table.column + * + * @var array + */ + protected $enum_map = array(); + + /** + * Return a enum type-formatted string + * + * enums are not supported. as a workaround to store allowed values we creates an additional table + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function enum($values){ + $tablefield = $values['table'] . '.' . $values['name']; + $enumValues = implode(',', $values['enums']); + + // Ensure the cache table exists + if(empty($this->enum_map)) { + $this->query("CREATE TABLE IF NOT EXISTS \"SQLiteEnums\" (\"TableColumn\" TEXT PRIMARY KEY, \"EnumList\" TEXT)"); + } + + // Ensure the table row exists + if(empty($this->enum_map[$tablefield]) || $this->enum_map[$tablefield] != $enumValues) { + $this->preparedQuery( + "REPLACE INTO SQLiteEnums (TableColumn, EnumList) VALUES (?, ?)", + array($tablefield, $enumValues) + ); + $this->enum_map[$tablefield] = $enumValues; + } + + // Set default + if(!empty($values['default'])) { + $default = str_replace(array('"',"'","\\","\0"), "", $values['default']); + return "TEXT DEFAULT '$default'"; + } else { + return 'TEXT'; + } + } + + /** + * Return a set type-formatted string + * This type doesn't exist in SQLite either + * + * @see SQLite3SchemaManager::enum() + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function set($values) { + return $this->enum($values); + } + + /** + * Return a float type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function float($values, $asDbValue = false){ + return "REAL"; + } + + /** + * Return a Double type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function double($values, $asDbValue = false){ + return "REAL"; + } + + /** + * Return a int type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function int($values, $asDbValue = false){ + return "INTEGER({$values['precision']}) " . strtoupper($values['null']) . " DEFAULT " . (int)$values['default']; + } + + /** + * Return a datetime type-formatted string + * For SQLite3, we simply return the word 'TEXT', no other parameters are necessary + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function ss_datetime($values, $asDbValue = false) { + return "DATETIME"; + } + + /** + * Return a text type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function text($values, $asDbValue = false) { + return 'TEXT'; + } + + /** + * Return a time type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function time($values) { + return "TEXT"; + } + + /** + * Return a varchar type-formatted string + * + * @params array $values Contains a tokenised list of info about this data type + * @return string + */ + public function varchar($values, $asDbValue = false) { + return "VARCHAR({$values['precision']}) COLLATE NOCASE"; + } + + /* + * Return a 4 digit numeric type. MySQL has a proprietary 'Year' type. + * For SQLite3 we use TEXT + */ + public function year($values, $asDbValue = false){ + return "TEXT"; + } + + public function IdColumn($asDbValue = false, $hasAutoIncPK = true){ + return 'INTEGER PRIMARY KEY AUTOINCREMENT'; + } + + function hasTable($tableName) { + return (bool)$this->preparedQuery( + 'SELECT name FROM sqlite_master WHERE type = ? AND name = ?', + array('table', $tableName) + )->first(); + } + + /** + * Return enum values for the given field + * + * @return array + */ + public function enumValuesForField($tableName, $fieldName) { + $tablefield = "$tableName.$fieldName"; + + // Check already cached values for this field + if(!empty($this->enum_map[$tablefield])) { + return explode(',', $this->enum_map[$tablefield]); + } + + // Retrieve and cache these details from the database + $classnameinfo = $this->preparedQuery( + "SELECT EnumList FROM SQLiteEnums WHERE TableColumn = ?", + array($tablefield) + )->first(); + if($classnameinfo) { + $valueList = $classnameinfo['EnumList']; + $this->enum_map[$tablefield] = $valueList; + return explode(',', $valueList); + } + + // Fallback to empty list + return array(); + } + + function dbDataType($type){ + $values = array( + 'unsigned integer' => 'INT' + ); + + if(isset($values[$type])) return $values[$type]; + else return ''; + } +} diff --git a/code/SQLiteDatabaseConfigurationHelper.php b/code/SQLiteDatabaseConfigurationHelper.php index 2c8302e..c415d43 100644 --- a/code/SQLiteDatabaseConfigurationHelper.php +++ b/code/SQLiteDatabaseConfigurationHelper.php @@ -1,51 +1,84 @@ getMessage(); + return null; + } + } + public function requireDatabaseFunctions($databaseConfig) { - if($databaseConfig['type'] == 'SQLitePDODatabase' || version_compare(phpversion(), '5.3.0', '<')) return class_exists('PDO') ? true : false; - return class_exists('SQLite3'); + $data = DatabaseAdapterRegistry::get_adapter($databaseConfig['type']); + return !empty($data['supported']); } - /** - * Ensure that the database server exists. - * @param array $databaseConfig Associative array of db configuration, e.g. "type", "path" etc - * @return array Result - e.g. array('success' => true, 'error' => 'details of error') - */ public function requireDatabaseServer($databaseConfig) { $path = $databaseConfig['path']; $error = ''; + $success = false; if(!$path) { - $success = false; $error = 'No database path provided'; - } - // check if parent folder is writeable - elseif(is_writable(dirname($path))) { + } elseif(is_writable($path) || (!file_exists($path) && is_writable(dirname($path)))) { + // check if folder is writeable $success = true; } else { - $success = false; - $error = 'Webserver can\'t write database file to path "' . $path . '"'; + $error = "Permission denied"; } return array( 'success' => $success, - 'error' => $error + 'error' => $error, + 'path' => $path ); } @@ -58,22 +91,18 @@ class SQLiteDatabaseConfigurationHelper implements DatabaseConfigurationHelper { * @return array Result - e.g. array('success' => true, 'error' => 'details of error') */ public function requireDatabaseConnection($databaseConfig) { - $success = false; - $error = ''; - - // arg validation - if(!isset($databaseConfig['path']) || !$databaseConfig['path']) return array( + // Do additional validation around file paths + if(empty($databaseConfig['path'])) return array( 'success' => false, - 'error' => sprintf('Invalid path: "%s"', $databaseConfig['path']) + 'error' => "Missing directory path" ); + if(empty($databaseConfig['database'])) return array( + 'success' => false, + 'error' => "Missing database filename" + ); + + // Create and secure db directory $path = $databaseConfig['path']; - - if(!isset($databaseConfig['database']) || !$databaseConfig['database']) return array( - 'success' => false, - 'error' => sprintf('Invalid database name: "%s"', $databaseConfig['database']) - ); - - // create and secure db directory $dirCreated = self::create_db_dir($path); if(!$dirCreated) return array( 'success' => false, @@ -85,21 +114,8 @@ class SQLiteDatabaseConfigurationHelper implements DatabaseConfigurationHelper { 'error' => sprintf('Cannot secure path through .htaccess: "%s"', $path) ); - $file = $path . '/' . $databaseConfig['database']; - $file = preg_replace('/\/$/', '', $file); - - if($databaseConfig['type'] == 'SQLitePDODatabase' || version_compare(phpversion(), '5.3.0', '<')) { - $conn = @(new PDO("sqlite:$file")); - } else { - $conn = @(new SQLite3($file, SQLITE3_OPEN_READWRITE | SQLITE3_OPEN_CREATE)); - } - - if($conn) { - $success = true; - } else { - $success = false; - $error = ''; - } + $conn = $this->createConnection($databaseConfig, $error); + $success = !empty($conn); return array( 'success' => $success, @@ -110,21 +126,19 @@ class SQLiteDatabaseConfigurationHelper implements DatabaseConfigurationHelper { public function getDatabaseVersion($databaseConfig) { $version = 0; - - if(class_exists('SQLite3')) { - $info = SQLite3::version(); - if($info && isset($info['versionString'])) { + + switch($databaseConfig['type']) { + case 'SQLite3Database': + $info = SQLite3::version(); $version = trim($info['versionString']); - } - } else { - // Fallback to using sqlite_version() query - $file = $databaseConfig['path'] . '/' . $databaseConfig['database']; - $file = preg_replace('/\/$/', '', $file); - $conn = @(new PDO("sqlite:$file")); - if($conn) { - $result = @$conn->query('SELECT sqlite_version()'); - $version = $result->fetchColumn(); - } + break; + case 'SQLite3PDODatabase': + // Fallback to using sqlite_version() query + $conn = $this->createConnection($databaseConfig, $error); + if($conn) { + $version = $conn->getAttribute(PDO::ATTR_SERVER_VERSION); + } + break; } return $version; @@ -148,29 +162,9 @@ class SQLiteDatabaseConfigurationHelper implements DatabaseConfigurationHelper { ); } - /** - * Ensure that the database connection is able to use an existing database, - * or be able to create one if it doesn't exist. - * - * @param array $databaseConfig Associative array of db configuration, e.g. "server", "username" etc - * @return array Result - e.g. array('success' => true, 'alreadyExists' => 'true') - */ public function requireDatabaseOrCreatePermissions($databaseConfig) { - $success = false; - $alreadyExists = false; - $canCreate = false; - - $check = $this->requireDatabaseConnection($databaseConfig); - $conn = $check['connection']; - - if($conn) { - $success = true; - $alreadyExists = true; - } else { - $success = false; - $alreadyExists = false; - } - + $conn = $this->createConnection($databaseConfig, $error); + $success = $alreadyExists = !empty($conn); return array( 'success' => $success, 'alreadyExists' => $alreadyExists, @@ -186,7 +180,7 @@ class SQLiteDatabaseConfigurationHelper implements DatabaseConfigurationHelper { * @return boolean */ public static function create_db_dir($path) { - return (!file_exists($path)) ? mkdir($path) : true; + return file_exists($path) || mkdir($path); } /** @@ -203,14 +197,11 @@ class SQLiteDatabaseConfigurationHelper implements DatabaseConfigurationHelper { return (is_writeable($path)) ? file_put_contents($path . '/.htaccess', 'deny from all') : false; } - /** - * Ensure we have permissions to alter tables. - * - * @param array $databaseConfig Associative array of db configuration, e.g. "server", "username" etc - * @return array Result - e.g. array('okay' => true, 'applies' => true), where applies is whether - * the test is relevant for the database - */ public function requireDatabaseAlterPermissions($databaseConfig) { - return array('success' => true, 'applies' => false); + // no concept of table-specific permissions; If you can connect you can alter schema + return array( + 'success' => true, + 'applies' => false + ); } } diff --git a/code/SQLitePDODatabase.php b/code/SQLitePDODatabase.php deleted file mode 100644 index 89efadf..0000000 --- a/code/SQLitePDODatabase.php +++ /dev/null @@ -1,178 +0,0 @@ -enum_map = array(); - $parameters = $this->parameters; - - if(!empty($parameters['memory'])) { - Deprecation::notice( - '1.4.0', - "\$databaseConfig['memory'] is deprecated. Use \$databaseConfig['path'] = ':memory:' instead.", - Deprecation::SCOPE_GLOBAL - ); - $parameters['path'] = ':memory:'; - } - - $dbName = !isset($this->database) ? $parameters['database'] : $dbName=$this->database; - $file = $parameters['path']; - - // assumes that the path to dbname will always be provided - // this is only necessary if we're using a filesystem path, and not an in-memory database - if($file != ':memory:') { - $file = $parameters['path'] . '/' . $dbName; - if(!file_exists($parameters['path'])) { - SQLiteDatabaseConfigurationHelper::create_db_dir($parameters['path']); - SQLiteDatabaseConfigurationHelper::secure_db_dir($parameters['path']); - } - } - - $this->dbConn = new PDO("sqlite:$file"); - - $this->active = true; - $this->database = $dbName; - - if(!$this->dbConn) { - $this->databaseError("Couldn't connect to SQLite3 database"); - return false; - } - - foreach(self::$default_pragma as $pragma => $value) $this->pragma($pragma, $value); - - if(empty(self::$default_pragma['locking_mode'])) { - self::$default_pragma['locking_mode'] = $this->pragma('locking_mode'); - } - - return true; - } - - public function query($sql, $errorLevel = E_USER_ERROR) { - - if(isset($_REQUEST['previewwrite']) && in_array(strtolower(substr($sql,0,strpos($sql,' '))), array('insert','update','delete','replace'))) { - Debug::message("Will execute: $sql"); - return; - } - - if(isset($_REQUEST['showqueries'])) { - $starttime = microtime(true); - } - - // @todo This is a very ugly hack to rewrite the update statement of SiteTree::doPublish() - // @see SiteTree::doPublish() There is a hack for MySQL already, maybe it's worth moving this to SiteTree or that other hack to Database... - if(preg_replace('/[\W\d]*/i','',$sql) == 'UPDATESiteTree_LiveSETSortSiteTreeSortFROMSiteTreeWHERESiteTree_LiveIDSiteTreeIDANDSiteTree_LiveParentID') { - preg_match('/\d+/i',$sql,$matches); - $sql = 'UPDATE "SiteTree_Live" - SET "Sort" = (SELECT "SiteTree"."Sort" FROM "SiteTree" WHERE "SiteTree_Live"."ID" = "SiteTree"."ID") - WHERE "ParentID" = ' . $matches[0]; - } - - @$handle = $this->dbConn->query($sql); - - if(isset($_REQUEST['showqueries'])) { - $endtime = round(microtime(true) - $starttime,4); - Debug::message("\n$sql\n{$endtime}ms\n", false); - } - - DB::$lastQuery=$handle; - - if(!$handle && $errorLevel) { - $msg = $this->dbConn->errorInfo(); - $this->databaseError("Couldn't run query: $sql | " . $msg[2], $errorLevel); - } - - return new SQLitePDOQuery($this, $handle); - } - - public function getGeneratedID($table) { - return $this->dbConn->lastInsertId(); - } - - /* - * This will return text which has been escaped in a database-friendly manner - */ - function addslashes($value){ - return str_replace("'", "''", $value); - } -} - -/** - * A result-set from a SQLitePDO database. - * @package SQLite3 - */ -class SQLitePDOQuery extends SQLite3Query { - - /** - * Hook the result-set given into a Query class, suitable for use by framework. - * @param database The database object that created this query. - * @param handle the internal sqlitePDO handle that is points to the resultset. - */ - public function __construct(SQLitePDODatabase $database, PDOStatement $handle) { - $this->database = $database; - $this->handle = $handle; - } - - public function __destruct() { - if($this->handle) $this->handle->closeCursor(); - } - - public function __destroy() { - $this->handle->closeCursor(); - } - - public function seek($row) { - $this->handle->execute(); - $i=0; - while($i < $row && $row = $this->handle->fetch()) $i++; - return (bool) $row; - } - - public function numRecords() { - return $this->handle->rowCount(); - } - - public function nextRecord() { - $this->handle->setFetchMode( PDO::FETCH_CLASS, 'ResultRow'); - if($data = $this->handle->fetch(PDO::FETCH_CLASS)) { - foreach($data->get() as $columnName => $value) { - if(preg_match('/^"([a-z0-9_]+)"\."([a-z0-9_]+)"$/i', $columnName, $matches)) $columnName = $matches[2]; - else if(preg_match('/^"([a-z0-9_]+)"$/i', $columnName, $matches)) $columnName = $matches[1]; - else $columnName = trim($columnName,"\"' \t"); - $output[$columnName] = is_null($value) ? null : (string)$value; - } - return $output; - } else { - return false; - } - } -} - -/** - * This is necessary for a case where we have ambigous fields in the result. - * E.g. we have something like the following: - * SELECT Child1.value, Child2.value FROM Parent LEFT JOIN Child1 LEFT JOIN Child2 - * We get value twice in the result set. We want the last not empty value. - * The fetch assoc syntax does'nt work because it gives us the last value everytime, empty or not. - * The fetch num does'nt work because there is no function to retrieve the field names to create the map. - * In this approach we make use of PDO fetch class to pass the result values to an - * object and let the __set() function do the magic decision to choose the right value. - */ -class ResultRow { - private $_datamap=array(); - - function __set($key,$val) { - if($val || !isset($this->_datamap[$key])) $this->_datamap[$key] = $val; - } - - function get() { - return $this->_datamap; - } -}