From 55946ffda6335ffff484c39b3a69daf415cc6edf Mon Sep 17 00:00:00 2001 From: skodak Date: Sun, 22 Jun 2008 21:35:07 +0000 Subject: [PATCH] MDL-15071 new sqlite pdo driver by Andrei Bautu (with minor changes) --- admin/environment.xml | 1 + install.php | 12 +- install/stringnames.txt | 3 + lang/en_utf8/install.php | 9 + lib/ddl/sqlite_sql_generator.php | 306 ++++++++++++++ lib/dml/pdo_moodle_database.php | 530 +++++++++++++++++++++--- lib/dml/pdo_moodle_recordset.php | 25 +- lib/dml/sqlite3_pdo_moodle_database.php | 319 ++++++++++++++ 8 files changed, 1144 insertions(+), 61 deletions(-) create mode 100644 lib/ddl/sqlite_sql_generator.php create mode 100644 lib/dml/sqlite3_pdo_moodle_database.php diff --git a/admin/environment.xml b/admin/environment.xml index ff9f987f37856..a189c3c77f6db 100644 --- a/admin/environment.xml +++ b/admin/environment.xml @@ -214,6 +214,7 @@ + diff --git a/install.php b/install.php index 9d133724ae67d..68900a0af5519 100644 --- a/install.php +++ b/install.php @@ -168,7 +168,8 @@ 'mssql_n_adodb', 'mssql_adodb', 'odbc_mssql_adodb', - 'oci8po_adodb' + 'oci8po_adodb', + 'sqlite3_pdo', ); $databases = array (); foreach($supported as $driver) { @@ -320,7 +321,7 @@ error_reporting(0); // Hide errors if (! $dbconnected = $DB->connect($INSTALL['dbhost'], $INSTALL['dbuser'], $INSTALL['dbpass'], $INSTALL['dbname'], false, $INSTALL['prefix'])) { - if (!$DB->create_database($INSTALL['dbhost'], $INSTALL['dbuser'], $INSTALL['dbpass'])) { + if (!$DB->create_database($INSTALL['dbhost'], $INSTALL['dbuser'], $INSTALL['dbpass'], $INSTALL['dbname'])) { $errormsg = get_string('dbcreationerror', 'install'); $nextstage = DATABASE; } else { @@ -472,6 +473,13 @@ } else { $str .= '$CFG->'.$key.' = false;'."\r\n"; } + } else if (is_array($value)) { + if (empty($value)) { + $value = 'array()'; + } else { + $value = 'unserialize(\'' . addsingleslashes(serialize($value)) . '\')'; + } + $str .= '$CFG->'.$key.' = '. $value . ";\r\n"; } else { $str .= '$CFG->'.$key.' = \''.addsingleslashes($value)."';\r\n"; } diff --git a/install/stringnames.txt b/install/stringnames.txt index 9913ac28e766d..8b17f03a16aef 100644 --- a/install/stringnames.txt +++ b/install/stringnames.txt @@ -67,6 +67,7 @@ databasesettingssub_mysqli databasesettingssub_oci8po databasesettingssub_odbc_mssql databasesettingssub_postgres7 +databasesettingssub_sqlite3_pdo databasesettingswillbecreated databasetype databaseuser @@ -207,6 +208,8 @@ sitenewsitems siteshortname sitesummary skipdbencodingtest +sqlite3_pdo +sqliteextensionisnotpresentinphp status this_direction tableprefix diff --git a/lang/en_utf8/install.php b/lang/en_utf8/install.php index 2ee29e53c790e..96b7f0bdafd0e 100644 --- a/lang/en_utf8/install.php +++ b/lang/en_utf8/install.php @@ -129,6 +129,13 @@ User: your database username
Password: your database password
Tables Prefix: prefix to use for all table names (mandatory)'; +$string['databasesettingssub_sqlite3_pdo'] = 'Type: SQLite 3 (PDO) Experimental! (not for use in production)
+ Host: path to the directory where the database file will be saved (use a full path); use localhost or leave blank to use Moodle data directory
+ Name: database name, eg moodle (optional)
+ User: your database username (optional)
+ Password: your database password (optional)
+ Tables Prefix: optional prefix to use for all table names
+ The name of the database file will be determined by the username, database name and password you entered above.'; $string['databasesettingswillbecreated'] = 'Note: The installer will try to create the database automatically if not exists.'; $string['databasetype']='Database type :'; $string['databaseuser']='Database user :'; @@ -325,6 +332,8 @@ $string['siteshortname'] = 'Site short name :'; $string['sitesummary'] ='Site summary :'; $string['skipdbencodingtest'] = 'Skip DB Encoding Test'; +$string['sqlite3_pdo'] = 'SQLite 3 (PDO) Experimental! (not for use in production)'; +$string['sqliteextensionisnotpresentinphp'] = 'PHP has not been properly configured with the SQLite extension. Please check your php.ini file or recompile PHP.'; $string['tableprefix']='Table prefix :'; $string['upgradingactivitymodule']= 'Upgrading Activity Module'; $string['upgradingbackupdb'] = 'Upgrading Backup Database'; diff --git a/lib/ddl/sqlite_sql_generator.php b/lib/ddl/sqlite_sql_generator.php new file mode 100644 index 0000000000000..3896dfddacc67 --- /dev/null +++ b/lib/ddl/sqlite_sql_generator.php @@ -0,0 +1,306 @@ +libdir.'/ddl/sql_generator.php'); + +/// This class generate SQL code to be used against SQLite +/// It extends XMLDBgenerator so everything can be +/// overriden as needed to generate correct SQL. + +class sqlite_sql_generator extends sql_generator { + +/// Only set values that are different from the defaults present in XMLDBgenerator + + public $drop_default_value_required = true; //To specify if the generator must use some DEFAULT clause to drop defaults + public $drop_default_value = NULL; //The DEFAULT clause required to drop defaults + + public $drop_primary_key = 'ALTER TABLE TABLENAME DROP PRIMARY KEY'; // Template to drop PKs + // with automatic replace for TABLENAME and KEYNAME + + public $drop_unique_key = 'ALTER TABLE TABLENAME DROP KEY KEYNAME'; // Template to drop UKs + // with automatic replace for TABLENAME and KEYNAME + + public $drop_foreign_key = 'ALTER TABLE TABLENAME DROP FOREIGN KEY KEYNAME'; // Template to drop FKs + // with automatic replace for TABLENAME and KEYNAME + public $default_for_char = ''; // To define the default to set for NOT NULLs CHARs without default (null=do nothing) + + public $sequence_only = true; //To avoid to output the rest of the field specs, leaving only the name and the sequence_name publiciable + public $sequence_extra_code = false; //Does the generator need to add extra code to generate the sequence fields + public $sequence_name = 'INTEGER PRIMARY KEY AUTOINCREMENT'; //Particular name for inline sequences in this generator + public $unsigned_allowed = false; // To define in the generator must handle unsigned information + + public $enum_extra_code = false; //Does the generator need to add extra code to generate code for the enums in the table + + public $add_after_clause = true; // Does the generator need to add the after clause for fields + + public $concat_character = null; //Characters to be used as concatenation operator. If not defined + //MySQL CONCAT function will be use + + public $alter_column_sql = 'ALTER TABLE TABLENAME MODIFY COLUMN COLUMNSPECS'; //The SQL template to alter columns + + public $drop_index_sql = 'ALTER TABLE TABLENAME DROP INDEX INDEXNAME'; //SQL sentence to drop one index + //TABLENAME, INDEXNAME are dinamically replaced + + public $rename_index_sql = null; //SQL sentence to rename one index (MySQL doesn't support this!) + //TABLENAME, OLDINDEXNAME, NEWINDEXNAME are dinamically replaced + + public $rename_key_sql = null; //SQL sentence to rename one key (MySQL doesn't support this!) + //TABLENAME, OLDKEYNAME, NEWKEYNAME are dinamically replaced + + /** + * Creates one new XMLDBmysql + */ + public function __construct($mdb) { + parent::__construct($mdb); + } + + /** + * Given one correct xmldb_key, returns its specs + */ + public function getKeySQL($xmldb_table, $xmldb_key) { + + $key = ''; + + switch ($xmldb_key->getType()) { + case XMLDB_KEY_PRIMARY: + if ($this->primary_keys && count($xmldb_key->getFields())>1) { + if ($this->primary_key_name !== null) { + $key = $this->getEncQuoted($this->primary_key_name); + } else { + $key = $this->getNameForObject($xmldb_table->getName(), implode(', ', $xmldb_key->getFields()), 'pk'); + } + $key .= ' PRIMARY KEY (' . implode(', ', $this->getEncQuoted($xmldb_key->getFields())) . ')'; + } + break; + case XMLDB_KEY_UNIQUE: + if ($this->unique_keys) { + $key = $this->getNameForObject($xmldb_table->getName(), implode(', ', $xmldb_key->getFields()), 'uk'); + $key .= ' UNIQUE (' . implode(', ', $this->getEncQuoted($xmldb_key->getFields())) . ')'; + } + break; + case XMLDB_KEY_FOREIGN: + case XMLDB_KEY_FOREIGN_UNIQUE: + if ($this->foreign_keys) { + $key = $this->getNameForObject($xmldb_table->getName(), implode(', ', $xmldb_key->getFields()), 'fk'); + $key .= ' FOREIGN KEY (' . implode(', ', $this->getEncQuoted($xmldb_key->getFields())) . ')'; + $key .= ' REFERENCES ' . $this->getEncQuoted($this->prefix . $xmldb_key->getRefTable()); + $key .= ' (' . implode(', ', $this->getEncQuoted($xmldb_key->getRefFields())) . ')'; + } + break; + } + + return $key; + } + + /** + * Given one XMLDB Type, lenght and decimals, returns the DB proper SQL type + */ + public function getTypeSQL($xmldb_type, $xmldb_length=null, $xmldb_decimals=null) { + + switch ($xmldb_type) { + case XMLDB_TYPE_INTEGER: // From http://www.sqlite.org/datatype3.html + if (empty($xmldb_length)) { + $xmldb_length = 10; + } + $dbtype = 'INTEGER(' . $xmldb_length . ')'; + break; + case XMLDB_TYPE_NUMBER: + $dbtype = $this->number_type; + if (!empty($xmldb_length)) { + $dbtype .= '(' . $xmldb_length; + if (!empty($xmldb_decimals)) { + $dbtype .= ',' . $xmldb_decimals; + } + $dbtype .= ')'; + } + break; + case XMLDB_TYPE_FLOAT: + $dbtype = 'REAL'; + if (!empty($xmldb_length)) { + $dbtype .= '(' . $xmldb_length; + if (!empty($xmldb_decimals)) { + $dbtype .= ',' . $xmldb_decimals; + } + $dbtype .= ')'; + } + break; + case XMLDB_TYPE_CHAR: + $dbtype = 'VARCHAR'; + if (empty($xmldb_length)) { + $xmldb_length='255'; + } + $dbtype .= '(' . $xmldb_length . ')'; + break; + case XMLDB_TYPE_BINARY: + $dbtype = 'BLOB'; + break; + case XMLDB_TYPE_DATETIME: + $dbtype = 'DATETIME'; + default: + case XMLDB_TYPE_TEXT: + $dbtype = 'TEXT'; + break; + } + return $dbtype; + } + + /** + * Given one xmldb_table and one xmldb_field, return the SQL statements needded to create its enum + * (usually invoked from getModifyEnumSQL() + */ + public function getCreateEnumSQL($xmldb_table, $xmldb_field) { + /// For MySQL, just alter the field + return $this->getAlterFieldSQL($xmldb_table, $xmldb_field); + } + + /** + * Given one xmldb_table and one xmldb_field, return the SQL statements needded to drop its enum + * (usually invoked from getModifyEnumSQL() + */ + public function getDropEnumSQL($xmldb_table, $xmldb_field) { + /// For MySQL, just alter the field + return $this->getAlterFieldSQL($xmldb_table, $xmldb_field); + } + + /** + * Given one xmldb_table and one xmldb_field, return the SQL statements needded to create its default + * (usually invoked from getModifyDefaultSQL() + */ + public function getCreateDefaultSQL($xmldb_table, $xmldb_field) { + /// Just a wrapper over the getAlterFieldSQL() function for MySQL that + /// is capable of handling defaults + return $this->getAlterFieldSQL($xmldb_table, $xmldb_field); + } + + /** + * Given one correct xmldb_field and the new name, returns the SQL statements + * to rename it (inside one array) + * SQLite is pretty diferent from the standard to justify this oveloading + */ + public function getRenameFieldSQL($xmldb_table, $xmldb_field, $newname) { + + // TODO: Add code to rename column + + /// Need a clone of xmldb_field to perform the change leaving original unmodified + $xmldb_field_clone = clone($xmldb_field); + + /// Change the name of the field to perform the change + $xmldb_field_clone->setName($xmldb_field_clone->getName() . ' ' . $newname); + + $fieldsql = $this->getFieldSQL($xmldb_field_clone); + + $sql = 'ALTER TABLE ' . $this->getTableName($xmldb_table) . ' CHANGE ' . $fieldsql; + + return array($sql); + } + + /** + * Given one xmldb_table and one xmldb_field, return the SQL statements needded to drop its default + * (usually invoked from getModifyDefaultSQL() + */ + public function getDropDefaultSQL($xmldb_table, $xmldb_field) { + /// Just a wrapper over the getAlterFieldSQL() function for MySQL that + /// is capable of handling defaults + return $this->getAlterFieldSQL($xmldb_table, $xmldb_field); + } + + /** + * Given one XMLDB Field, return its enum SQL + */ + public function getEnumSQL($xmldb_field) { + return 'enum'; + } + + /** + * Returns the code (in array) needed to add one comment to the table + */ + function getCommentSQL ($xmldb_table) { + return array(); + } + + /** + * Given one xmldb_table returns one array with all the check constrainsts + * in the table (fetched from DB) + * Optionally the function allows one xmldb_field to be specified in + * order to return only the check constraints belonging to one field. + * Each element contains the name of the constraint and its description + * If no check constraints are found, returns an empty array + * MySQL doesn't have check constraints in this implementation, but + * we return them based on the enum fields in the table + */ + public function getCheckConstraintsFromDB($xmldb_table, $xmldb_field = null) { + + // TODO: add code for constraints + return array(); + } + + /** + * Given one object name and it's type (pk, uk, fk, ck, ix, uix, seq, trg) + * return if such name is currently in use (true) or no (false) + * (invoked from getNameForObject() + */ + public function isNameInUse($object_name, $type, $table_name) { + // TODO: add introspection code + return false; //No name in use found + } + + + /** + * Returns an array of reserved words (lowercase) for this DB + */ + public static function getReservedWords() { + /// From http://www.sqlite.org/lang_keywords.html + $reserved_words = array ( + 'ADD', 'ALL', 'ALTER', 'AND', 'AS', 'AUTOINCREMENT', + 'BETWEEN', 'BY', + 'CASE', 'CHECK', 'COLLATE', 'COLUMN', 'COMMIT', 'CONSTRAINT', 'CREATE', 'CROSS', + 'DEFAULT', 'DEFERRABLE', 'DELETE', 'DISTINCT', 'DROP', + 'ELSE', 'ESCAPE', 'EXCEPT', 'EXISTS', + 'FOREIGN', 'FROM', 'FULL', + 'GROUP', + 'HAVING', + 'IN', 'INDEX', 'INNER', 'INSERT', 'INTERSECT', 'INTO', 'IS', 'ISNULL', + 'JOIN', + 'LEFT', 'LIMIT', + 'NATURAL', 'NOT', 'NOTNULL', 'NULL', + 'ON', 'OR', 'ORDER', 'OUTER', + 'PRIMARY', + 'REFERENCES', 'REGEXP', 'RIGHT', 'ROLLBACK', + 'SELECT', 'SET', + 'TABLE', 'THEN', 'TO', 'TRANSACTION', + 'UNION', 'UNIQUE', 'UPDATE', 'USING', + 'VALUES', + 'WHEN', 'WHERE', + ); + return $reserved_words; + } + + public function addslashes($s) { + // do not use php addslashes() because it depends on PHP quote settings! + $s = str_replace("'", "''", $s); + return $s; + } +} diff --git a/lib/dml/pdo_moodle_database.php b/lib/dml/pdo_moodle_database.php index 5f1167ac2b909..52aee4c43ccfc 100644 --- a/lib/dml/pdo_moodle_database.php +++ b/lib/dml/pdo_moodle_database.php @@ -10,15 +10,44 @@ abstract class pdo_moodle_database extends moodle_database { protected $pdb; + protected $debug = false; + protected $lastError = null; - //TODO: This looks incorrect now IMO. Construct should have only external and connect get all the rest of params - public function __construct($dbhost, $dbuser, $dbpass, $dbname, $dbpersist, $prefix, array $dboptions=null, $external=false) { - parent::__construct($dbhost, $dbuser, $dbpass, $dbname, $dbpersist, $prefix, $dboptions, $external); + /** + * Contructor - instantiates the database, specifying if it's external (connect to other systems) or no (Moodle DB) + * note this has effect to decide if prefix checks must be performed or no + * @param bool true means external database used + */ + public function __construct($external=false) { + parent::__construct($external); } - public function connect() { + /** + * Connect to db + * Must be called before other methods. + * @param string $dbhost + * @param string $dbuser + * @param string $dbpass + * @param string $dbname + * @param bool $dbpersist + * @param mixed $prefix string means moodle db prefix, false used for external databases where prefix not used + * @param array $dboptions driver specific options + * @return bool success + */ + public function connect($dbhost, $dbuser, $dbpass, $dbname, $dbpersist, $prefix, array $dboptions=null) { + $this->dbhost = $dbhost; + $this->dbuser = $dbuser; + $this->dbpass = $dbpass; + $this->dbname = $dbname; + $this->dbpersist = $dbpersist; + $this->prefix = $prefix; + $this->dboptions = (array)$dboptions; + try { - $this->pdb = new PDO('mysql:host='.$this->dbhost.';dbname='.$this->dbname, $this->dbuser, $this->pass, array(PDO::ATTR_PERSISTENT => $this->dbpresist)); + $this->pdb = new PDO($this->get_dsn(), $this->dbuser, $this->dbpass, $this->get_pdooptions()); + // generic PDO settings to match adodb's default; subclasses can change this in configure_dbconnection + $this->pdb->setAttribute(PDO::ATTR_CASE, PDO::CASE_LOWER); + $this->pdb->setAttribute(PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION); $this->configure_dbconnection(); return true; } catch (PDOException $ex) { @@ -26,97 +55,480 @@ public function connect() { } } - ///TODO: not needed preconfigure_dbconnection() stuff for PDO drivers? + /** + * Returns the driver-dependent DSN for PDO based on members stored by connect. + * Must be called after connect (or after $dbname, $dbhost, etc. members have been set). + * @return string driver-dependent DSN + */ + protected function get_dsn() { + return 'mysql:host='.$this->dbhost.';dbname='.$this->dbname; + } + + /** + * Returns the driver-dependent connection attributes for PDO based on members stored by connect. + * Must be called after $dbname, $dbhost, etc. members have been set. + * @return array A key=>value array of PDO driver-specific connection options + */ + protected function get_pdooptions() { + return array(PDO::ATTR_PERSISTENT => $this->dbpresist); + } + protected function configure_dbconnection() { + ///TODO: not needed preconfigure_dbconnection() stuff for PDO drivers? } - public function get_columns($table, $usecache=true) { - if ($usecache and isset($this->columns[$table])) { - return $this->columns[$table]; - } + /** + * Returns localised database type name + * Note: can be used before connect() + * @return string + */ + public function get_name() { + return get_string($this->get_dbtype() . '_pdo', 'install'); + } - if (!$this->columns[$table] = array_change_key_case($this->db->MetaColumns($this->prefix.$table), CASE_LOWER)) { - $this->columns[$table] = array(); - } + /** + * Returns localised database description + * Note: can be used before connect() + * @return string + */ + public function get_configuration_hints() { + return get_string('databasesettingssub_' . $this->get_dbtype() . '_pdo', 'install'); + } - return $this->columns[$table]; + /** + * Returns db related part of config.php + * Note: can be used before connect() + * @return string + */ + public function export_dbconfig() { + $cfg = new stdClass(); + $cfg->dbtype = $this->get_dbtype(); + $cfg->dblibrary = 'pdo'; + $cfg->dbhost = $this->dbhost; + $cfg->dbname = $this->dbname; + $cfg->dbuser = $this->dbuser; + $cfg->dbpass = $this->dbpass; + $cfg->prefix = $this->prefix; + $cfg->dboptions = $this->dboptions; + return $cfg; } - protected function report_error($sql, $params, $obj) { + /** + * Returns database server info array + * @return array + */ + public function get_server_info() { + $result = array(); + try { + $result['description'] = $this->pdb->getAttribute(PDO::ATTR_SERVER_INFO); + } catch(PDOException $ex) {} + try { + $result['version'] = $this->pdb->getAttribute(PDO::ATTR_SERVER_VERSION); + } catch(PDOException $ex) {} + return $result; + } + + /** + * Returns supported query parameter types + * @return bitmask + */ + protected function allowed_param_types() { + return SQL_PARAMS_QM | SQL_PARAMS_NAMED; + } + + /** + * Returns last error reported by database engine. + */ + public function get_last_error() { + return $this->lastError; + } + + protected function report_error($sql, $params, $e) { debugging($e->getMessage() .'

'. s($sql)); } + /** + * Enable/disable very detailed debugging + * TODO: do we need levels? + * @param bool $state + */ public function set_debug($state) { - //TODO + $this->debug = $state; + } + + /** + * Returns debug status + * @return bool $state + */ + public function get_debug() { + return $this->debug; } + /** + * Enable/disable detailed sql logging + * TODO: do we need levels? + * @param bool $state + */ public function set_logging($state) { //TODO } - public function execute($sql, array $params=null) { - try { - list($sql, $params, $type) = $this->fix_sql_params($sql, $params); - $sth = $this->dbh->prepare($sql); - return $sth->execute($params); - } catch (PDOException $ex) { - $this->report_error($sql, $params, $ex); - return false; + /** + * Function to print/save/ignore debuging messages related to SQL queries. + */ + protected function debug_query($sql, $params = null) { + echo '
(', $this->get_dbtype(), '): ', htmlentities($sql); + if($params) { + echo ' (parameters '; + print_r($params); + echo ')'; } + echo '
'; + } + + /** + * Do NOT use in code, to be used by database_manager only! + * @param string $sql query + * @return bool success + */ + public function change_database_structure($sql) { + return $this->execute($sql); } public function delete_records_select($table, $select, array $params=null) { + $sql = "DELETE FROM {{$table}}"; + if ($select) { + $sql .= " WHERE $select"; + } + $this->writes++; + return $this->execute($sql, $params); + } + + /** + * Factory method that creates a recordset for return by a query. The generic pdo_moodle_recordset + * class should fit most cases, but pdo_moodle_database subclasses can overide this method to return + * a subclass of pdo_moodle_recordset. + * @param object $sth instance of PDOStatement + * @return object instance of pdo_moodle_recordset + */ + protected function create_recordset($sth) { + return new pdo_moodle_recordset($sth); + } + + /** + * Execute general sql query. Should be used only when no other method suitable. + * Do NOT use this to make changes in db structure, use database_manager::execute_sql() instead! + * @param string $sql query + * @param array $params query parameters + * @return bool success + */ + public function execute($sql, array $params=null) { try { - if ($select) { - $select = "WHERE $select"; - } - $sql = "DELETE FROM {$this->prefix}$table $select"; + $this->lastError = null; list($sql, $params, $type) = $this->fix_sql_params($sql, $params); - $sth = $this->dbh->prepare($sql); - return $sth->execute($params); + if($this->debug) { + $this->debug_query($sql, $params); + } + $sth = $this->pdb->prepare($sql); + $sth->execute($params); + return true; } catch (PDOException $ex) { + $this->lastError = $ex->getMessage(); $this->report_error($sql, $params, $ex); return false; } } + /** + * Get a number of records as an moodle_recordset. $sql must be a complete SQL query. + * Since this method is a little less readable, use of it should be restricted to + * code where it's possible there might be large datasets being returned. For known + * small datasets use get_records_sql - it leads to simpler code. + * + * The return type is as for @see function get_recordset. + * + * @param string $sql the SQL select query to execute. + * @param array $params array of sql parameters + * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set). + * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set). + * @return mixed an moodle_recorset object, or false if an error occured. + */ public function get_recordset_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) { try { + $this->lastError = null; list($sql, $params, $type) = $this->fix_sql_params($sql, $params); - $sth = $this->dbh->prepare($sql); - error('TODO'); + $sql = $this->get_limit_clauses($sql, $limitfrom, $limitnum); + if($this->debug) { + $this->debug_query($sql, $params); + } + $this->reads++; + $sth = $this->pdb->prepare($sql); + $sth->execute($params); return $this->create_recordset($sth); - } catch (PDOException $ex) { + $this->lastError = $ex->getMessage(); $this->report_error($sql, $params, $ex); return false; } } + + /** + * Returns the sql statement with clauses to append used to limit a recordset range. + * @param string $sql the SQL statement to limit. + * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set). + * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set). + * @return string the SQL statement with limiting clauses + */ + protected function get_limit_clauses($sql, $limitfrom=0, $limitnum=0) { + return $sql; + } - protected function create_recordset($sth) { - return new pdo_moodle_recordset($sth); + /** + * Selects rows and return values of first column as array. + * + * @param string $sql The SQL query + * @param array $params array of sql parameters + * @return mixed array of values or false if an error occured + */ + public function get_fieldset_sql($sql, array $params=null) { + if(!$rs = $this->get_recordset_sql($sql, $params)) { + return false; + } + $result = array(); + foreach($rs as $value) { + $result[] = reset($value); + } + $rs->close(); + return $result; } + /** + * Get a number of records as an array of objects. + * + * Return value as for @see function get_records. + * + * @param string $sql the SQL select query to execute. The first column of this SELECT statement + * must be a unique value (usually the 'id' field), as it will be used as the key of the + * returned array. + * @param array $params array of sql parameters + * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set). + * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set). + * @return mixed an array of objects, or empty array if no records were found, or false if an error occured. + */ public function get_records_sql($sql, array $params=null, $limitfrom=0, $limitnum=0) { - try { - list($sql, $params, $type) = $this->fix_sql_params($sql, $params); - error('TODO'); + if(!$rs = $this->get_recordset_sql($sql, $params, $limitfrom, $limitnum)) { + return false; + } + $objects = array(); + $debugging = debugging('', DEBUG_DEVELOPER); + foreach($rs as $value) { + $key = reset($value); + if ($debugging && array_key_exists($key, $objects)) { + debugging("Did you remember to make the first column something unique in your call to get_records? Duplicate value '$key' found in column first column of '$sql'.", DEBUG_DEVELOPER); + } + $objects[$key] = (object)$value; + } + $rs->close(); + return $objects; + } - } catch (PDOException $ex) { - $this->report_error($sql, $params, $ex); + /** + * Insert new record into database, as fast as possible, no safety checks, lobs not supported. + * @param string $table name + * @param mixed $params data record as object or array + * @param bool $returnit return it of inserted record + * @param bool $bulk true means repeated inserts expected + * @return mixed success or new id + */ + public function insert_record_raw($table, $params, $returnid=true, $bulk=false) { + if (!is_array($params)) { + $params = (array)$params; + } + unset($params['id']); + + if (empty($params)) { + return false; + } + + $this->writes++; + + $fields = implode(',', array_keys($params)); + $qms = array_fill(0, count($params), '?'); + $qms = implode(',', $qms); + + $sql = "INSERT INTO {{$table}} ($fields) VALUES($qms)"; + if (!$this->execute($sql, $params)) { + return false; + } + if (!$returnid) { + return true; + } + if ($id = $this->pdb->lastInsertId()) { + return (int)$id; + } + return false; + } + + /** + * Insert a record into a table and return the "id" field if required, + * Some conversions and safety checks are carried out. Lobs are supported. + * If the return ID isn't required, then this just reports success as true/false. + * $data is an object containing needed data + * @param string $table The database table to be inserted into + * @param object $data A data object with values for one or more fields in the record + * @param bool $returnid Should the id of the newly created record entry be returned? If this option is not requested then true/false is returned. + * @param bool $bulk true means repeated inserts expected + * @return mixed success or new ID + */ + public function insert_record($table, $dataobject, $returnid=true, $bulk=false) { + if (!is_object($dataobject)) { + $dataobject = (object)$dataobject; + } + + $columns = $this->get_columns($table); + + unset($dataobject->id); + $cleaned = array(); + + foreach ($dataobject as $field=>$value) { + if (!isset($columns[$field])) { + continue; + } + $column = $columns[$field]; + if (is_bool($value)) { + $value = (int)$value; // prevent "false" problems + } + if (!empty($column->enums)) { + if (!in_array((string)$value, $column->enums)) { + debugging('Enum value '.s($value).' not allowed in field '.$field.' table '.$table.'.'); + return false; + } + } + $cleaned[$field] = $value; + } + + if (empty($cleaned)) { return false; } + + return $this->insert_record_raw($table, $cleaned, $returnid, $bulk); } + + /** + * Update record in database, as fast as possible, no safety checks, lobs not supported. + * @param string $table name + * @param mixed $params data record as object or array + * @param bool true means repeated updates expected + * @return bool success + */ + public function update_record_raw($table, $params, $bulk=false) { + if (!is_array($params)) { + $params = (array)$params; + } + if (!isset($params['id'])) { + return false; + } + $id = $params['id']; + unset($params['id']); - public function get_fieldset_sql($sql, array $params=null) { - try { - list($sql, $params, $type) = $this->fix_sql_params($sql, $params); - error('TODO'); + if (empty($params)) { + return false; + } - } catch (PDOException $ex) { - $this->report_error($sql, $params, $ex); + $sets = array(); + foreach ($params as $field=>$value) { + $sets[] = "$field = ?"; + } + + $params[] = $id; // last ? in WHERE condition + + $sets = implode(',', $sets); + $sql = "UPDATE {{$table}} SET $sets WHERE id=?"; + $this->writes++; + return $this->execute($sql, $params); + } + + /** + * Update a record in a table + * + * $dataobject is an object containing needed data + * Relies on $dataobject having a variable "id" to + * specify the record to update + * + * @param string $table The database table to be checked against. + * @param object $dataobject An object with contents equal to fieldname=>fieldvalue. Must have an entry for 'id' to map to the table specified. + * @param bool true means repeated updates expected + * @return bool success + */ + public function update_record($table, $dataobject, $bulk=false) { + if (!is_object($dataobject)) { + $dataobject = (object)$dataobject; + } + + if (!isset($dataobject->id) ) { return false; } + + $columns = $this->get_columns($table); + $cleaned = array(); + + foreach ($dataobject as $field=>$value) { + if (!isset($columns[$field])) { + continue; + } + if (is_bool($value)) { + $value = (int)$value; // prevent "false" problems + } + $cleaned[$field] = $value; + } + + return $this->update_record_raw($table, $cleaned, $bulk); + } + + /** + * Set a single field in every table row where the select statement evaluates to true. + * + * @param string $table The database table to be checked against. + * @param string $newfield the field to set. + * @param string $newvalue the value to set the field to. + * @param string $select A fragment of SQL to be used in a where clause in the SQL call. + * @param array $params array of sql parameters + * @return bool success + */ + public function set_field_select($table, $newfield, $newvalue, $select, array $params=null) { + if ($select) { + $select = "WHERE $select"; + } + if (is_null($params)) { + $params = array(); + } + list($select, $params, $type) = $this->fix_sql_params($select, $params); + + if (is_bool($newvalue)) { + $newvalue = (int)$newvalue; // prevent "false" problems + } + if (is_null($newvalue)) { + $newfield = "$newfield = NULL"; + } else { + // make sure SET and WHERE clauses use the same type of parameters, + // because we don't support different types in the same query + switch($type) { + case SQL_PARAMS_NAMED: + $newfield = "$newfield = :newvalueforupdate"; + $params['newvalueforupdate'] = $newvalue; + break; + case SQL_PARAMS_QM: + $newfield = "$newfield = ?"; + array_unshift($params, $newvalue); + break; + default: + $this->lastError = 'Unknown parameter type in file ' . __FILE__ . ' on line ' . __LINE__ . '.'; + error($this->lastError); + } + } + $sql = "UPDATE {{$table}} SET $newfield $select"; + $this->writes++; + return $this->execute($sql, $params); } public function sql_substr() { @@ -132,16 +544,28 @@ public function sql_concat_join($separator="' '", $elements=array()) { } public function begin_sql() { - $this->pdb->beginTransaction(); - return true; + try { + $this->pdb->beginTransaction(); + return true; + } catch(PDOException $ex) { + return false; + } } public function commit_sql() { - $this->pdb->commit(); - return true; + try { + $this->pdb->commit(); + return true; + } catch(PDOException $ex) { + return false; + } } + public function rollback_sql() { - $this->pdb->rollBack(); - return true; + try { + $this->pdb->rollBack(); + return true; + } catch(PDOException $ex) { + return false; + } } - } diff --git a/lib/dml/pdo_moodle_recordset.php b/lib/dml/pdo_moodle_recordset.php index fee26e8b44f17..063a33f674180 100644 --- a/lib/dml/pdo_moodle_recordset.php +++ b/lib/dml/pdo_moodle_recordset.php @@ -8,30 +8,43 @@ */ class pdo_moodle_recordset extends moodle_recordset { - private $sht; + private $sth; + protected $fields; + protected $rowCount = -1; public function __construct($sth) { $this->sth = $sth; + $this->sth->setFetchMode(PDO::FETCH_ASSOC); } public function current() { - error('TODO'); + return (object)$this->fields; } public function key() { - error('TODO'); + return $this->rowCount; } public function next() { - error('TODO'); + $this->fields = $this->sth->fetch(); + if ($this->fields) { + ++$this->rowCount; + } + return $this->fields !== false; } public function rewind() { - error('TODO'); + $this->fields = $this->sth->fetch(); + if ($this->fields) { + $this->rowCount = 0; + } } public function valid() { - error('TODO'); + if($this->rowCount < 0) { + $this->rewind(); + } + return $this->fields !== FALSE; } public function close() { diff --git a/lib/dml/sqlite3_pdo_moodle_database.php b/lib/dml/sqlite3_pdo_moodle_database.php new file mode 100644 index 0000000000000..a8e4397ce52d5 --- /dev/null +++ b/lib/dml/sqlite3_pdo_moodle_database.php @@ -0,0 +1,319 @@ +libdir.'/dml/pdo_moodle_database.php'); + +/** + * Experimental pdo database class + * @package dmlib + */ +class sqlite3_pdo_moodle_database extends pdo_moodle_database { + protected $database_file_extension = '.sq3.php'; + /** + * Detects if all needed PHP stuff installed. + * Note: can be used before connect() + * @return mixed true if ok, string if something + */ + public function driver_installed() { + if (!extension_loaded('pdo_sqlite')) + return get_string('sqliteextensionisnotpresentinphp', 'install'); + return true; + } + + /** + * Returns database family type - describes SQL dialect + * Note: can be used before connect() + * @return string db family name (mysql, postgres, mssql, oracle, etc.) + */ + public function get_dbfamily() { + return 'sqlite'; + } + + /** + * Returns more specific database driver type + * Note: can be used before connect() + * @return string db type mysql, mysqli, postgres7 + */ + protected function get_dbtype() { + return 'sqlite3'; + } + + protected function configure_dbconnection() { + // try to protect database file agains web access; + // this is required in case that the moodledata folder is web accessible and + // .htaccess is not in place; requires that the database file extension is php + $this->pdb->exec('CREATE TABLE IF NOT EXISTS "" (id int)'); + $this->pdb->exec('PRAGMA synchronous=OFF'); + $this->pdb->exec('PRAGMA short_column_names=1'); + $this->pdb->exec('PRAGMA encoding="UTF-8"'); + $this->pdb->exec('PRAGMA case_sensitive_like=0'); + $this->pdb->exec('PRAGMA locking_mode=NORMAL'); + } + + /** + * Attempt to create the database + * @param string $dbhost + * @param string $dbuser + * @param string $dbpass + * @param string $dbname + * + * @return bool success + */ + public function create_database($dbhost, $dbuser, $dbpass, $dbname) { + $this->dbhost = $dbhost; + $this->dbuser = $dbuser; + $this->dbpass = $dbpass; + $this->dbname = $dbname; + $filepath = $this->get_dbfilepath(); + $dirpath = dirname($filepath); + @mkdir($dirpath); + return touch($filepath); + } + + /** + * Returns the driver-dependent DSN for PDO based on members stored by connect. + * Must be called after connect (or after $dbname, $dbhost, etc. members have been set). + * @return string driver-dependent DSN + */ + public function get_dsn() { + return 'sqlite:' . $this->get_dbfilepath(); + } + + /** + * Returns the file path for the database file, computed from dbname and/or dboptions. + * If dboptions['file'] is set, then it is used (use :memory: for in memory database); + * else if dboptions['path'] is set, then the file will be /.sq3.php; + * else if dbhost is set and not localhost, then the file will be /.sq3.php; + * else the file will be /.sq3.php + * @return string file path to the SQLite database; + */ + public function get_dbfilepath() { + global $CFG; + if(!empty($this->dboptions['file'])) { + return $this->dboptions['file']; + } + if($this->dbhost && $this->dbhost != 'localhost') { + $path = $this->dbhost; + } else { + $path = $CFG->dataroot; + } + $path = ltrim($path, '\\/') . '/'; + if(!empty($this->dbuser)) { + $path .= $this->dbuser . '_'; + } + $path .= $this->dbname . '_' . md5($this->dbpass) . $this->database_file_extension; + return $path; + } + + /** + * Return tables in database WITHOUT current prefix + * @return array of table names in lowercase and without prefix + */ + public function get_tables() { + $tables = array(); + $sql = 'SELECT name FROM sqlite_master WHERE type="table"'; + if($this->debug) { + $this->debug_query($sql); + } + $rstables = $this->pdb->query($sql); + foreach ($rstables as $table) { + $table = $table['name']; + $table = strtolower($table); + if (empty($this->prefix) || strpos($table, $this->prefix) === 0) { + $table = substr($table, strlen($this->prefix)); + $tables[$table] = $table; + } + } + return $tables; + } + + /** + * Return table indexes - everything lowercased + * @return array of arrays + */ + public function get_indexes($table) { + $indexes = array(); + $sql = 'SELECT * FROM sqlite_master WHERE type="index" AND tbl_name="'. $this->prefix . $table . '"'; + if($this->debug) { + $this->debug_query($sql); + } + $rsindexes = $this->pdb->query($sql); + foreach($rsindexes as $index) { + $index = strtolower($index['name']); + $sql = 'PRAGMA index_info("' . $index . '")'; + if($this->debug) { + $this->debug_query($sql); + } + $rscolumns = $this->pdb->query($sql); + $columns = array(); + foreach($rscolumns as $row) { + $columns[] = strtolower($row['name']); + } + $index = strtolower($index); + $indexes[$index]['columns'] = $columns; + } + return $indexes; + } + + /** + * Returns datailed information about columns in table. This information is cached internally. + * @param string $table name + * @param bool $usecache + * @return array array of database_column_info objects indexed with column names + */ + public function get_columns($table, $usecache=true) { + if ($usecache and isset($this->columns[$table])) { + return $this->columns[$table]; + } + // get table's CREATE TABLE command (we'll need it for autoincrement fields) + $sql = 'SELECT sql FROM sqlite_master WHERE type="table" AND tbl_name="'. $this->prefix . $table . '"'; + if($this->debug) { + $this->debug_query($sql); + } + $createsql = $this->pdb->query($sql)->fetch(); + if(!$createsql) { + return false; + } + $createsql = $createsql['sql']; + + $columns = array(); + $sql = 'PRAGMA table_info("'. $this->prefix . $table . '")'; + if($this->debug) { + $this->debug_query($sql); + } + $rscolumns = $this->pdb->query($sql); + foreach ($rscolumns as $row) { + $columninfo = array( + 'name' => strtolower($row['name']), // colum names must be lowercase + 'not_null' =>(boolean)$row['notnull'], + 'primary_key' => (boolean)$row['pk'], + 'has_default' => !is_null($row['dflt_value']), + 'default_value' => $row['dflt_value'], + ); + $type = explode('(', $row['type']); + $columninfo['type'] = strtolower($type[0]); + if(count($type) > 1) { + $size = explode(',', trim($type[1], ')')); + $columninfo['max_length'] = $size[0]; + if(count($size) > 1) { + $columninfo['scale'] = $size[1]; + } + } + // SQLite does not have a fixed set of datatypes (ie. it accepts any string as + // datatype in the CREATE TABLE command. We try to guess which type is used here + switch(substr($columninfo['type'], 0, 3)) { + case 'int': // int integer + if($columninfo['primary_key'] && preg_match('/' . $columninfo['name'] . '\W*integer\W*primary\W*key\W*autoincrement/im', $createsql)) { + $columninfo['meta_type'] = 'R'; + } else { + $columninfo['meta_type'] = 'I'; + } + break; + case 'num': // number numeric + case 'rea': // real + case 'dou': // double + case 'flo': // float + $columninfo['meta_type'] = 'N'; + break; + case 'var': // varchar + case 'cha': // char + $columninfo['meta_type'] = 'C'; + break; + case 'tex': // text + case 'clo': // clob + $columninfo['meta_type'] = 'X'; + break; + case 'blo': // blob + case 'non': // none + $columninfo['meta_type'] = 'B'; + break; + case 'boo': // boolean + case 'bit': // bit + case 'log': // logical + $columninfo['meta_type'] = 'L'; + break; + case 'tim': // timestamp + $columninfo['meta_type'] = 'T'; + break; + case 'dat': // date datetime + $columninfo['meta_type'] = 'D'; + break; + } + + $columns[$columninfo['name']] = new database_column_info($columninfo); + } + + $this->columns[$table] = $columns; + return $columns; + } + + /** + * Returns the sql statement with clauses to append used to limit a recordset range. + * @param string $sql the SQL statement to limit. + * @param int $limitfrom return a subset of records, starting at this point (optional, required if $limitnum is set). + * @param int $limitnum return a subset comprising this many records (optional, required if $limitfrom is set). + * @return string the SQL statement with limiting clauses + */ + protected function get_limit_clauses($sql, $limitfrom=0, $limitnum=0) { + if($limitnum) { + $sql .= ' LIMIT ' . $limitnum; + if($limitfrom) { + $sql .= ' OFFSET ' . $limitfrom; + } + } + return $sql; + } + + /** + * Delete the records from a table where all the given conditions met. + * If conditions not specified, table is truncated. + * + * @param string $table the table to delete from. + * @param array $conditions optional array $fieldname=>requestedvalue with AND in between + * @return returns success. + */ + public function delete_records($table, array $conditions=null) { + if (is_null($conditions)) { + return $this->execute("DELETE FROM {{$table}}"); + } + list($select, $params) = $this->where_clause($conditions); + return $this->delete_records_select($table, $select, $params); + } + + /** + * Returns the proper substr() function for each DB + */ + public function sql_substr() { + return 'substr'; + } + + /** + * Returns the proper SQL to do CONCAT between the elements passed + * Can take many parameters + * + * @param string $element + * @return string + */ + public function sql_concat() { + $elements = func_get_args(); + return implode('||', $elements); + } + + /** + * Returns the proper SQL to do CONCAT between the elements passed + * with a given separator + * + * @param string $separator + * @param array $elements + * @return string + */ + public function sql_concat_join($separator="' '", $elements=array()) { + // Intersperse $elements in the array. + // Add items to the array on the fly, walking it + // _backwards_ splicing the elements in. The loop definition + // should skip first and last positions. + for ($n=count($elements)-1; $n > 0 ; $n--) { + array_splice($elements, $n, 0, $separator); + } + return implode('||', $elements); + } +} \ No newline at end of file