From abe3843012e611654a2e9eb15f33ec81fe4c89c4 Mon Sep 17 00:00:00 2001 From: Damian Mooyman Date: Wed, 3 Apr 2013 17:27:11 +1300 Subject: [PATCH] API Upgraded module to use new database ORM --- _config.php | 2 - _config/connectors.yml | 16 + _config/postgresql.yml | 32 + _register_database.php | 25 + code/PostgreSQLConnector.php | 248 ++ code/PostgreSQLDatabase.php | 2361 +++-------------- .../PostgreSQLDatabaseConfigurationHelper.php | 217 +- code/PostgreSQLQuery.php | 41 + code/PostgreSQLSchemaManager.php | 1445 ++++++++++ docs/README.md | 8 +- docs/en/README.md | 8 +- tests/PostgreSQLConnectorTest.php | 49 + tests/PostgreSQLDatabaseTest.php | 12 +- 13 files changed, 2339 insertions(+), 2125 deletions(-) create mode 100644 _config/connectors.yml create mode 100644 _config/postgresql.yml create mode 100644 _register_database.php create mode 100644 code/PostgreSQLConnector.php create mode 100644 code/PostgreSQLQuery.php create mode 100644 code/PostgreSQLSchemaManager.php create mode 100644 tests/PostgreSQLConnectorTest.php diff --git a/_config.php b/_config.php index 15c5adc..b3d9bbc 100644 --- a/_config.php +++ b/_config.php @@ -1,3 +1 @@ \ No newline at end of file diff --git a/_config/connectors.yml b/_config/connectors.yml new file mode 100644 index 0000000..944acbe --- /dev/null +++ b/_config/connectors.yml @@ -0,0 +1,16 @@ +--- +name: postgresqlconnectors +--- +Injector: + PostgrePDODatabase: + class: 'PostgrePDODatabase' + properties: + connector: %$PDOConnector + schemaManager: %$PostgreSQLSchemaManager + queryBuilder: %$DBQueryBuilder + PostgreSQLDatabase: + class: 'PostgreSQLDatabase' + properties: + connector: %$PostgreSQLConnector + schemaManager: %$PostgreSQLSchemaManager + queryBuilder: %$DBQueryBuilder \ No newline at end of file diff --git a/_config/postgresql.yml b/_config/postgresql.yml new file mode 100644 index 0000000..3854d83 --- /dev/null +++ b/_config/postgresql.yml @@ -0,0 +1,32 @@ +PostgreSQLDatabase: +# Determines whether to check a database exists on the host by +# querying the 'postgres' database and running createDatabase. +# +# Some locked down systems prevent access to the 'postgres' table in +# which case you need to set this to false. +# +# If allow_query_master_postgres is false, and model_schema_as_database is also false, +# then attempts to create or check databases beyond the initial connection will +# result in a runtime error. + allow_query_master_postgres: true +# For instances where multiple databases are used beyond the initial connection +# you may set this option to true to force database switches to switch schemas +# instead of using databases. This may be useful if the database user does not +# have cross-database permissions, and in cases where multiple databases are used +# (such as in running test cases). +# +# If this is true then the database will only be set during the initial connection, +# and attempts to change to this database will use the 'public' schema instead +# +# If this is false then errors may be generated during some cross database operations. + model_schema_as_database: true +# Override the language that tsearch uses. By default it is 'english, but +# could be any of the supported languages that can be found in the +# pg_catalog.pg_ts_config table. + search_language: 'english' +# These two values describe how T-search will work. +# You can use either GiST or GIN, and '@@' (gist) or '@@@' (gin) +# Combinations of these two will also work, so you'll need to pick +# one which works best for you + default_fts_cluster_method: 'GIN' + default_fts_search_method: '@@@' \ No newline at end of file diff --git a/_register_database.php b/_register_database.php new file mode 100644 index 0000000..63d7cd5 --- /dev/null +++ b/_register_database.php @@ -0,0 +1,25 @@ + 'PostgrePDODatabase', + 'title' => 'PostgreSQL 8.3+ (using PDO)', + 'helperPath' => dirname(__FILE__).'/code/PostgreSQLDatabaseConfigurationHelper.php', + 'supported' => (class_exists('PDO') && in_array('postgresql', PDO::getAvailableDrivers())), + 'missingExtensionText' => + 'Either the PDO Extension or + the SQL Server PDO Driver + are unavailable. Please install or enable these and refresh this page.' +)); + + +// PDO Postgre database +DatabaseAdapterRegistry::register(array( + 'class' => 'PostgreSQLDatabase', + 'title' => 'PostgreSQL 8.3+ (using pg_connect)', + 'helperPath' => dirname(__FILE__).'/code/PostgreSQLDatabaseConfigurationHelper.php', + 'supported' => function_exists('pg_connect'), + 'missingExtensionText' => + 'The pgsql PHP extension is not + available. Please install or enable it and refresh this page.' +)); diff --git a/code/PostgreSQLConnector.php b/code/PostgreSQLConnector.php new file mode 100644 index 0000000..ca77118 --- /dev/null +++ b/code/PostgreSQLConnector.php @@ -0,0 +1,248 @@ +lastParameters = $parameters; + + // Note: Postgres always behaves as though $selectDB = true, ignoring + // any value actually passed in. The controller passes in true for other + // connectors such as PDOConnector. + + // Escape parameters + $arguments = array( + $this->escapeParameter($parameters, 'server', 'host', 'localhost'), + $this->escapeParameter($parameters, 'port', 'port', 5432), + $this->escapeParameter($parameters, 'database', 'dbname', 'postgres'), + $this->escapeParameter($parameters, 'username', 'user'), + $this->escapeParameter($parameters, 'password', 'password') + ); + + // Close the old connection + if($this->dbConn) pg_close($this->dbConn); + + // Connect + $this->dbConn = @pg_connect(implode(' ', $arguments)); + if($this->dbConn === false) { + // Extract error details from PHP error handling + $error = error_get_last(); + if($error && preg_match('/function\\.pg-connect\\<\\/a\\>\\]\\: (?.*)/', $error['message'], $matches)) { + $this->databaseError(html_entity_decode($matches['message'])); + } else { + $this->databaseError("Couldn't connect to PostgreSQL database."); + } + } elseif(pg_connection_status($this->dbConn) != PGSQL_CONNECTION_OK) { + throw new ErrorException($this->getLastError()); + } + + //By virtue of getting here, the connection is active: + $this->databaseName = empty($parameters['database']) ? PostgreSQLDatabase::MASTER_DATABASE : $parameters['database']; + } + + public function affectedRows() { + return $this->lastRows; + } + + public function getGeneratedID($table) { + $result = $this->query("SELECT last_value FROM \"{$table}_ID_seq\";")->first(); + return $result['last_value']; + } + + public function getLastError() { + return pg_last_error($this->dbConn); + } + + public function getSelectedDatabase() { + return $this->databaseName; + } + + public function getVersion() { + $version = pg_version($this->dbConn); + if(isset($version['server'])) return $version['server']; + else return false; + } + + public function isActive() { + return $this->databaseName && $this->dbConn; + } + + /** + * Determines if the SQL fragment either breaks into or out of a string literal + * by counting single quotes + * + * Handles double-quote escaped quotes as well as slash escaped quotes + * + * @todo Test this! + * + * @see http://www.postgresql.org/docs/8.3/interactive/sql-syntax-lexical.html#SQL-SYNTAX-STRINGS + * + * @param string $input The SQL fragment + * @return boolean True if the string breaks into or out of a string literal + */ + public function checkStringTogglesLiteral($input) { + // Remove escaped backslashes, count them! + $input = preg_replace('/\\\\\\\\/', '', $input); + + // Count quotes + $totalQuotes = substr_count($input, "'"); // Includes double quote escaped quotes + $escapedQuotes = substr_count($input, "\\'"); + return (($totalQuotes - $escapedQuotes) % 2) !== 0; + } + + /** + * Iteratively replaces all question marks with numerical placeholders + * E.g. "Title = ? AND Name = ?" becomes "Title = $1 AND Name = $2" + * + * @todo Better consider question marks in string literals + * + * @param string $sql Paramaterised query using question mark placeholders + * @return string Paramaterised query using numeric placeholders + */ + public function replacePlaceholders($sql) { + $segments = preg_split('/\?/', $sql); + $joined = ''; + $inString = false; + for($i = 0; $i < count($segments); $i++) { + // Append next segment + $joined .= $segments[$i]; + + // Don't add placeholder after last segment + if($i === count($segments) - 1) break; + + // check string escape on previous fragment + if($this->checkStringTogglesLiteral($segments[$i])) { + $inString = !$inString; + } + + // Append placeholder replacement + $joined .= $inString ? "?" : ('$'.($i+1)); + } + return $joined; + } + + public function preparedQuery($sql, $parameters, $errorLevel = E_USER_ERROR) { + + // Replace question mark placeholders with numeric placeholders + if(!empty($parameters)) { + $sql = $this->replacePlaceholders($sql); + $parameters = $this->parameterValues($parameters); + } + + // Check if we should only preview this query + if ($this->previewWrite($sql)) return; + + // Benchmark query + $conn = $this->dbConn; + $this->lastQuery = $result = $this->benchmarkQuery($sql, function($sql) use($conn, $parameters) { + if(!empty($parameters)) { + return pg_query_params($conn, $sql, $parameters); + } else { + return pg_query($conn, $sql); + } + }); + $this->lastRows = 0; + if ($result === false) { + $this->databaseError($this->getLastError(), $errorLevel, $sql, $parameters); + return null; + } else { + $this->lastRows = pg_affected_rows($result); + } + + return new PostgreSQLQuery($result); + } + + public function query($sql, $errorLevel = E_USER_ERROR) { + return $this->preparedQuery($sql, array(), $errorLevel); + } + + public function quoteString($value) { + if(function_exists('pg_escape_literal')) { + return pg_escape_literal($this->dbConn, $value); + } else { + return "'" . $this->escapeString($value) . "'"; + } + } + + public function escapeString($value) { + return pg_escape_string($this->dbConn, $value); + } + + public function escapeIdentifier($value, $separator = '.') { + if(empty($separator) && function_exists('pg_escape_identifier')) { + return pg_escape_identifier($this->dbConn, $value); + } + + // Let parent function handle recursive calls + return parent::escapeIdentifier ($value, $separator); + } + + public function selectDatabase($name) { + if($name !== $this->databaseName) { + user_error("PostgreSQLConnector can't change databases. Please create a new database connection", E_USER_ERROR); + } + return true; + } + + public function unloadDatabase() { + $this->databaseName = null; + } +} diff --git a/code/PostgreSQLDatabase.php b/code/PostgreSQLDatabase.php index 2a9dc08..ea55416 100644 --- a/code/PostgreSQLDatabase.php +++ b/code/PostgreSQLDatabase.php @@ -1,64 +1,50 @@ get('PostgreSQLDatabase', 'default_fts_cluster_method'); + } - /* - * This holds the parameters that the original connection was created with, - * so we can switch back to it if necessary (used for unit tests) + /** + * Full text search method. + * + * @return string */ - private $parameters; - - /* - * These two values describe how T-search will work. - * You can use either GiST or GIN, and '@@' (gist) or '@@@' (gin) - * Combinations of these two will also work, so you'll need to pick - * one which works best for you - */ - public $default_fts_cluster_method='GIN'; - public $default_fts_search_method='@@@'; - - private $supportsTransactions=true; + public static function default_fts_search_method() { + return Config::inst()->get('PostgreSQLDatabase', 'default_fts_search_method'); + } /** * Determines whether to check a database exists on the host by @@ -66,36 +52,28 @@ class PostgreSQLDatabase extends SS_Database { * * Some locked down systems prevent access to the 'postgres' table in * which case you need to set this to false. + * + * If allow_query_master_postgres is false, and model_schema_as_database is also false, + * then attempts to create or check databases beyond the initial connection will + * result in a runtime error. */ - public static $check_database_exists = true; + public static function allow_query_master_postgres() { + return Config::inst()->get('PostgreSQLDatabase', 'allow_query_master_postgres'); + } /** - * This holds a copy of all the constraint results that are returned - * via the function constraintExists(). This is a bit faster than - * repeatedly querying this column, and should allow the database - * to use it's built-in caching features for better queries. - * - * @var array + * For instances where multiple databases are used beyond the initial connection + * you may set this option to true to force database switches to switch schemas + * instead of using databases. This may be useful if the database user does not + * have cross-database permissions, and in cases where multiple databases are used + * (such as in running test cases). + * + * If this is true then the database will only be set during the initial connection, + * and attempts to change to this database will use the 'public' schema instead */ - private static $cached_constraints=array(); - - /** - * - * This holds a copy of all the queries that run through the function orderMoreSpecifically() - * It appears to be a performance bottleneck at times. - * - * @var array - */ - private static $cached_ordered_specifically=array(); - - /** - * - * This holds a copy of all the queries that run through the function fieldList() - * This is one of the most-often called functions, and repeats itself a great deal in the unit tests. - * - * @var array - */ - private static $cached_fieldlists=array(); + public static function model_schema_as_database() { + return Config::inst()->get('PostgreSQLDatabase', 'model_schema_as_database'); + } /** * Override the language that tsearch uses. By default it is 'english, but @@ -104,112 +82,107 @@ class PostgreSQLDatabase extends SS_Database { * * @var string */ - private $search_language='english'; - - /** - * Connect to a PostgreSQL database. - * @param array $parameters An map of parameters, which should include: - * - server: The server, eg, localhost - * - username: The username to log on with - * - password: The password to log on with - * - database: The database to connect to - */ - 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; + public static function search_language() { + return Config::inst()->get('PostgreSQLDatabase', 'search_language'); } - /* - * Uses whatever connection details are in the $parameters array to connect to a database of a given name + /** + * The database name specified at initial connection + * + * @var string */ - function connectDatabase(){ + protected $databaseOriginal = ''; - $parameters=$this->parameters; + /** + * The schema name specified at initial construction. When model_schema_as_database + * is set to true selecting the $databaseOriginal database will instead reset + * the schema to this + * + * @var string + */ + protected $schemaOriginal = ''; - if(!$parameters) - return false; + /** + * Connection parameters specified at inital connection + * + * @var array + */ + protected $parameters = array(); - ($parameters['username']!='') ? $username=' user=' . $parameters['username'] : $username=''; - ($parameters['password']!='') ? $password=' password=\'' . $parameters['password'] . '\'' : $password=''; - - if(!isset($this->database)) - $dbName=$parameters['database']; - else $dbName=$this->database; - - $port = empty($parameters['port']) ? 5432 : $parameters['port']; - - // First, we need to check that this database exists. To do this, we will connect to the 'postgres' database first - // some setups prevent access to this database so set PostgreSQLDatabase::$check_database_exists = false - if(self::$check_database_exists) { - // Close the old connection - if($this->dbConn) pg_close($this->dbConn); - $this->dbConn = pg_connect('host=' . $parameters['server'] . ' port=' . $port . ' dbname=postgres' . $username . $password); - - if(!$this->dbConn) { - throw new ErrorException("Couldn't connect to PostgreSQL database"); - } elseif(pg_connection_status($this->dbConn) != PGSQL_CONNECTION_OK) { - throw new ErrorException(pg_last_error($this->dbConn)); + function connect($parameters) { + // Check database name + if(empty($parameters['database'])) { + // Check if we can use the master database + if(!self::allow_query_master_postgres()) { + throw new ErrorException('PostegreSQLDatabase::connect called without a database name specified'); } + // Fallback to master database connection if permission allows + $parameters['database'] = self::MASTER_DATABASE; + } + $this->databaseOriginal = $parameters['database']; - if(!$this->databaseExists($dbName)) { - $this->createDatabase($dbName); + // check schema name + if(empty($parameters['schema'])) { + $parameters['schema'] = self::MASTER_SCHEMA; + } + $this->schemaOriginal = $parameters['schema']; + + // Ensure that driver is available (required by PDO) + if(empty($parameters['driver'])) { + $parameters['driver'] = $this->getDatabaseServer(); + } + + // Ensure port number is set (required by postgres) + if(empty($parameters['port'])) { + $parameters['port'] = 5432; + } + + $this->parameters = $parameters; + + // If allowed, check that the database exists. Otherwise naively assume + // that the original database exists + if(self::allow_query_master_postgres()) { + // Use master connection to setup initial schema + $this->connectMaster(); + if(!$this->schemaManager->postgresDatabaseExists($this->databaseOriginal)) { + $this->schemaManager->createPostgresDatabase($this->databaseOriginal); } } - // Close the old connection - if($this->dbConn) pg_close($this->dbConn); - - //Now we can be sure that this database exists, so we can connect to it - $this->dbConn = pg_connect('host=' . $parameters['server'] . ' port=' . $port . ' dbname=' . $dbName . $username . $password); - - if(!$this->dbConn) { - throw new ErrorException("Couldn't connect to PostgreSQL database"); - } elseif(pg_connection_status($this->dbConn) != PGSQL_CONNECTION_OK) { - throw new ErrorException(pg_last_error($this->dbConn)); - } - - //By virtue of getting here, the connection is active: - $this->active=true; - $this->database = $dbName; + // Connect to the actual database we're requesting + $this->connectDefault(); // Set up the schema if required - $schema = isset($parameters['schema']) ? $parameters['schema'] : $this->currentSchema(); - // Edge-case - database with no schemas: - if(!$schema) $schema = "public"; - - if(!$this->schemaExists($schema)) - $this->createSchema($schema); - - $this->setSchema($schema); + $this->setSchema($this->schemaOriginal, true); // Set the timezone if required. - if(isset($parameters['timezone'])) $this->query(sprintf("SET SESSION TIME ZONE '%s'", $parameters['timezone'])); - - return true; + if (isset($parameters['timezone'])) { + $this->selectTimezone($parameters['timezone']); + } } - /** - * Not implemented, needed for PDO - */ - public function getConnect($parameters) { - return null; + + protected function connectMaster() { + $parameters = $this->parameters; + $parameters['database'] = self::MASTER_DATABASE; + $this->connector->connect($parameters, true); + } + + protected function connectDefault() { + $parameters = $this->parameters; + $parameters['database'] = $this->databaseOriginal; + $this->connector->connect($parameters, true); } /** - * Return the parameters used to construct this database connection + * Sets the system timezone for the database connection + * + * @param string $timezone */ - public function getParameters() { - return $this->parameters; + public function selectTimezone($timezone) { + if (empty($timezone)) return; + $this->query("SET SESSION TIME ZONE '$timezone';"); } - /** - * Returns true if this database supports collations - * TODO: get rid of this? - * @return boolean - */ public function supportsCollations() { return true; } @@ -218,1572 +191,66 @@ class PostgreSQLDatabase extends SS_Database { return true; } - /** - * Get the version of PostgreSQL. - * @return string - */ - public function getVersion() { - $version = pg_version($this->dbConn); - if(isset($version['server'])) return $version['server']; - else return false; - } - - /** - * Get the database server, namely PostgreSQL. - * @return string - */ public function getDatabaseServer() { return "postgresql"; } - 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 = pg_query($this->dbConn, $sql); - - if(isset($_REQUEST['showqueries'])) { - $endtime = round((microtime(true) - $starttime) * 1000, 1); - Debug::message("\n$sql\n{$endtime}ms\n", false); - } - - DB::$lastQuery=$handle; - - if(!$handle && $errorLevel) $this->databaseError("Couldn't run query: $sql | " . pg_last_error($this->dbConn), $errorLevel); - - return new PostgreSQLQuery($this, $handle); - } - - public function getGeneratedID($table) { - $result=DB::query("SELECT last_value FROM \"{$table}_ID_seq\";"); - $row=$result->first(); - return $row['last_value']; - } - - /** - * OBSOLETE: Get the ID for the next new record for the table. - * - * @var string $table The name od the table. - * @return int - */ - 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; - } - - /* - * You can create a database based either on a supplied name, or from whatever is in the $this->database value - */ - public function createDatabase($name=false) { - if(!$name) - $name=$this->database; - - $this->query("CREATE DATABASE \"$name\";"); - - $this->connectDatabase(); - - } - - /** - * Drop the database that this object is currently connected to. - * Use with caution. - */ - public function dropDatabase() { - - //First, we need to switch back to the original database so we can drop the current one - $db_to_drop=$this->database; - $this->selectDatabase($this->database_original); - - $this->query("DROP DATABASE \"$db_to_drop\""); - } - - /** - * Drop the database that this object is currently connected to. - * Use with caution. - */ - public function dropDatabaseByName($dbName) { - if($dbName!=$this->database) - $this->query("DROP DATABASE \"$dbName\";"); - } - - /** - * Returns the name of the currently selected database - */ - public function currentDatabase() { - return $this->database; - } - - /** - * Switches to the given database. - * If the database doesn't exist, you should call createDatabase() after calling selectDatabase() - */ - public function selectDatabase($dbname) { - $parameters=$this->parameters; - ($parameters['username']!='') ? $username=' user=' . $parameters['username'] : $username=''; - ($parameters['password']!='') ? $password=' password=\'' . $parameters['password'] . '\'' : $password=''; - - $port = empty($parameters['port']) ? 5432 : $parameters['port']; - - $this->database = $dbname; - $this->tableList = $this->fieldList = $this->indexList = null; - - // Switch to the database if it exists - if($this->databaseExists($dbname)) { - // Close old connection - if($this->dbConn) pg_close($this->dbConn); - $this->dbConn = pg_connect('host=' . $parameters['server'] . ' port=' . $port . ' dbname=' . $dbname . $username . $password); - - if(!$this->dbConn) { - throw new ErrorException("Couldn't connect to PostgreSQL database"); - } elseif(pg_connection_status($this->dbConn) != PGSQL_CONNECTION_OK) { - throw new ErrorException(pg_last_error($this->dbConn)); - } - - // Determine schema to use - $schema = isset($parameters['schema']) ? $parameters['schema'] : $this->currentSchema(); - if(!$schema) $schema = "public"; - - // Choose the schema - if(!$this->schemaExists($schema)) $this->createSchema($schema); - $this->setSchema($schema); - - // Set the timezone if required. - if(isset($parameters['timezone'])) $this->query(sprintf("SET SESSION TIME ZONE '%s'", $parameters['timezone'])); - - // Inactive database needs to be created; connect to the 'postgres' database in the meantime - } else { - // Close old connection - if($this->dbConn) pg_close($this->dbConn); - $this->dbConn = pg_connect('host=' . $parameters['server'] . ' port=' . $port . ' dbname=postgres' . $username . $password); - $this->active = false; - } - - return true; - } - - - /** - * Returns true if the named database exists. - */ - public function databaseExists($name) { - $SQL_name=$this->addslashes($name); - return $this->query("SELECT datname FROM pg_database WHERE datname='$SQL_name';")->first() ? true : false; - } - - /** - * Returns a column - */ - public function allDatabaseNames() { - return $this->query("SELECT datname FROM pg_database WHERE datistemplate=false;")->column(); - } - - /** - * Returns true if the schema exists in the current database - * @param string $name - * @return boolean - */ - public function schemaExists($name) { - $SQL_name = pg_escape_string($this->dbConn, $name); - return $this->query("SELECT nspname FROM pg_catalog.pg_namespace WHERE nspname = '{$SQL_name}';")->first() ? true : false; - } - - /** - * Creates a schema in the current database - * @param string $name - */ - public function createSchema($name) { - $SQL_name = pg_escape_string($this->dbConn, $name); - $this->query("CREATE SCHEMA \"{$SQL_name}\";"); - } - - /** - * Drops a schema from the database. Use carefully! - * @param string $name - */ - public function dropSchema($name) { - $SQL_name = pg_escape_string($this->dbConn, $name); - $this->query("DROP SCHEMA \"{$SQL_name}\" CASCADE;"); - } - /** * Returns the name of the current schema in use + * + * @return string Name of current schema */ public function currentSchema() { - return $this->query('SELECT current_schema()')->value(); - } - - /** - * Utility method to manually set the schema to an alternative - * Check existance & sets search path to the supplied schema name - * @param string $schema - */ - public function setSchema($schema) { - if(!$this->schemaExists($schema)) - $this->databaseError("Schema $schema does not exist"); - $this->setSchemaSearchPath($schema); - $this->schema = $schema; - } - - /** - * Override the schema search path. Search using the arguments supplied. - * NOTE: The search path is normally set through setSchema() and only - * one schema is selected. The facility to add more than one schema to - * the search path is provided as an advanced PostgreSQL feature for raw - * SQL queries. Sapphire cannot search for datamodel tables in alternate - * schemas, so be wary of using alternate schemas within the ORM environment. - * @param string $arg1 First schema to use - * @param string $arg2 Second schema to use - * @param string $argN Nth schema to use - */ - public function setSchemaSearchPath() { - if(func_num_args() == 0) - $this->databaseError('At least one Schema must be supplied to set a search path.'); - $args = array_values(func_get_args()); - foreach($args as $key => $schema) - $args[$key] = '"' . pg_escape_string($this->dbConn, $schema) . '"'; - $args_SQL =implode(",", $args); - $this->query("SET search_path TO {$args_SQL}"); - } - - public function createTable($tableName, $fields = null, $indexes = null, $options = null, $extensions = null) { - - $fieldSchemas = $indexSchemas = ""; - if($fields) foreach($fields as $k => $v) $fieldSchemas .= "\"$k\" $v,\n"; - if(isset($this->class)){ - $addOptions = (isset($options[$this->class])) ? $options[$this->class] : null; - } else $addOptions=null; - - //First of all, does this table already exist - $doesExist=$this->TableExists($tableName); - if($doesExist) { - // Table already exists, just return the name, in line with baseclass documentation. - return $tableName; - } - - //If we have a fulltext search request, then we need to create a special column - //for GiST searches - $fulltexts=''; - $triggers=''; - if($indexes){ - foreach($indexes as $name=>$this_index){ - if(is_array($this_index) && $this_index['type']=='fulltext'){ - $ts_details=$this->fulltext($this_index, $tableName, $name); - $fulltexts.=$ts_details['fulltexts'] . ', '; - $triggers.=$ts_details['triggers']; - } - } - } - - if($indexes) foreach($indexes as $k => $v) $indexSchemas .= $this->getIndexSqlDefinition($tableName, $k, $v) . "\n"; - - //Do we need to create a tablespace for this item? - if($extensions && isset($extensions['tablespace'])){ - - $this->createOrReplaceTablespace($extensions['tablespace']['name'], $extensions['tablespace']['location']); - $tableSpace=' TABLESPACE ' . $extensions['tablespace']['name']; - } else - $tableSpace=''; - - $this->query("CREATE TABLE \"$tableName\" ( - $fieldSchemas - $fulltexts - primary key (\"ID\") - )$tableSpace; $indexSchemas $addOptions"); - - if($triggers!=''){ - $this->query($triggers); - } - - //If we have a partitioning requirement, we do that here: - if($extensions && isset($extensions['partitions'])){ - $this->createOrReplacePartition($tableName, $extensions['partitions'], $indexes, $extensions); - } - - //Lastly, clustering goes here: - if($extensions && isset($extensions['cluster'])){ - DB::query("CLUSTER \"$tableName\" USING \"{$extensions['cluster']}\";"); - } - - return $tableName; + return $this->schema; } /** - * Builds the internal Postgres index name given the silverstripe table and index name - * @param string $tableName - * @param string $indexName - * @param string $prefix The optional prefix for the index. Defaults to "ix" for indexes. - * @return string The postgres name of the index - */ - function buildPostgresIndexName($tableName, $indexName, $prefix = 'ix') { - - // Assume all indexes also contain the table name - // MD5 the table/index name combo to keep it to a fixed length. - // Exclude the prefix so that the trigger name can be easily generated from the index name - $indexNamePG = "{$prefix}_" . md5("{$tableName}_{$indexName}"); - - // Limit to 63 characters - if (strlen($indexNamePG) > 63) - return substr($indexNamePG, 0, 63); - return $indexNamePG; - } - - /** - * Builds the internal Postgres trigger name given the silverstripe table and trigger name - * @param string $tableName - * @param string $triggerName - * @return string The postgres name of the trigger - */ - function buildPostgresTriggerName($tableName, $triggerName) { - // Kind of cheating, but behaves the same way as indexes - return $this->buildPostgresIndexName($tableName, $triggerName, 'ts'); - } - - /** - * 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) { - - $alterList = array(); - if($newFields) foreach($newFields as $fieldName => $fieldSpec) { - $alterList[] = "ADD \"$fieldName\" $fieldSpec"; - } - - if ($alteredFields) foreach ($alteredFields as $indexName => $indexSpec) { - $val = $this->alterTableAlterColumn($tableName, $indexName, $indexSpec); - if (!empty($val)) $alterList[] = $val; - } - - //Do we need to do anything with the tablespaces? - if($alteredOptions && isset($advancedOptions['tablespace'])){ - $this->createOrReplaceTablespace($advancedOptions['tablespace']['name'], $advancedOptions['tablespace']['location']); - $this->query("ALTER TABLE \"$tableName\" SET TABLESPACE {$advancedOptions['tablespace']['name']};"); - } - - //DB ABSTRACTION: we need to change the constraints to be a separate 'add' command, - //see http://www.postgresql.org/docs/8.1/static/sql-altertable.html - $alterIndexList=Array(); - //Pick up the altered indexes here: - $fieldList = $this->fieldList($tableName); - $fulltexts=false; - $drop_triggers=false; - $triggers=false; - if($alteredIndexes) foreach($alteredIndexes as $indexName=>$indexSpec) { - - $indexSpec = $this->parseIndexSpec($indexName, $indexSpec); - $indexNamePG = $this->buildPostgresIndexName($tableName, $indexName); - - if($indexSpec['type']=='fulltext') { - //For full text indexes, we need to drop the trigger, drop the index, AND drop the column - - //Go and get the tsearch details: - $ts_details = $this->fulltext($indexSpec, $tableName, $indexName); - - //Drop this column if it already exists: - - //No IF EXISTS option is available for Postgres <9.0 - if(array_key_exists($ts_details['ts_name'], $fieldList)){ - $fulltexts.="ALTER TABLE \"{$tableName}\" DROP COLUMN \"{$ts_details['ts_name']}\";"; - } - - // We'll execute these later: - $triggerNamePG = $this->buildPostgresTriggerName($tableName, $indexName); - $drop_triggers.= "DROP TRIGGER IF EXISTS \"$triggerNamePG\" ON \"$tableName\";"; - $fulltexts .= "ALTER TABLE \"{$tableName}\" ADD COLUMN {$ts_details['fulltexts']};"; - $triggers .= $ts_details['triggers']; - } - - // Create index action (including fulltext) - $alterIndexList[] = "DROP INDEX IF EXISTS \"$indexNamePG\";"; - $createIndex = $this->getIndexSqlDefinition($tableName, $indexName, $indexSpec); - if($createIndex!==false) $alterIndexList[] = $createIndex; - } - - //Add the new indexes: - if($newIndexes) foreach($newIndexes as $indexName => $indexSpec){ - - $indexSpec = $this->parseIndexSpec($indexName, $indexSpec); - $indexNamePG = $this->buildPostgresIndexName($tableName, $indexName); - //If we have a fulltext search request, then we need to create a special column - //for GiST searches - //Pick up the new indexes here: - if($indexSpec['type']=='fulltext') { - $ts_details=$this->fulltext($indexSpec, $tableName, $indexName); - if(!isset($fieldList[$ts_details['ts_name']])){ - $fulltexts.="ALTER TABLE \"{$tableName}\" ADD COLUMN {$ts_details['fulltexts']};"; - $triggers.=$ts_details['triggers']; - } - } - - //Check that this index doesn't already exist: - $indexes=$this->indexList($tableName); - if(isset($indexes[$indexName])){ - $alterIndexList[] = "DROP INDEX IF EXISTS \"$indexNamePG\";"; - } - - $createIndex=$this->getIndexSqlDefinition($tableName, $indexName, $indexSpec); - if($createIndex!==false) - $alterIndexList[] = $createIndex; - } - - if($alterList) { - $alterations = implode(",\n", $alterList); - $this->query("ALTER TABLE \"$tableName\" " . $alterations); - } - - //Do we need to create a tablespace for this item? - if($advancedOptions && isset($advancedOptions['extensions']['tablespace'])){ - $extensions=$advancedOptions['extensions']; - $this->createOrReplaceTablespace($extensions['tablespace']['name'], $extensions['tablespace']['location']); - } - - if($alteredOptions && isset($this->class) && isset($alteredOptions[$this->class])) { - $this->query(sprintf("ALTER TABLE \"%s\" %s", $tableName, $alteredOptions[$this->class])); - Database::alteration_message( - sprintf("Table %s options changed: %s", $tableName, $alteredOptions[$this->class]), - "changed" - ); - } - - //Create any fulltext columns and triggers here: - if($fulltexts) $this->query($fulltexts); - if($drop_triggers) $this->query($drop_triggers); - - if($triggers) { - $this->query($triggers); - - $triggerbits=explode(';', $triggers); - foreach($triggerbits as $trigger){ - $trigger_fields=$this->triggerFieldsFromTrigger($trigger); - - if($trigger_fields){ - //We need to run a simple query to force the database to update the triggered columns - $this->query("UPDATE \"{$tableName}\" SET \"{$trigger_fields[0]}\"=\"$trigger_fields[0]\";"); - } - } - } - - foreach($alterIndexList as $alteration) $this->query($alteration); - - //If we have a partitioning requirement, we do that here: - if($advancedOptions && isset($advancedOptions['partitions'])){ - $this->createOrReplacePartition($tableName, $advancedOptions['partitions']); - } - - //Lastly, clustering goes here: - if ($advancedOptions && isset($advancedOptions['cluster'])) { - $clusterIndex = $this->buildPostgresIndexName($tableName, $advancedOptions['cluster']); - DB::query("CLUSTER \"$tableName\" USING \"$clusterIndex\";"); - } else { - //Check that clustering is not on this table, and if it is, remove it: - - //This is really annoying. We need the oid of this table: - $stats=DB::query("SELECT relid FROM pg_stat_user_tables WHERE relname='" . $this->addslashes($tableName) . "';")->first(); - $oid=$stats['relid']; - - //Now we can run a long query to get the clustered status: - //If anyone knows a better way to get the clustered status, then feel free to replace this! - $clustered=DB::query("SELECT c2.relname, i.indisclustered FROM pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_index i WHERE c.oid = '$oid' AND c.oid = i.indrelid AND i.indexrelid = c2.oid AND indisclustered='t';")->first(); - - if($clustered) - DB::query("ALTER TABLE \"$tableName\" SET WITHOUT CLUSTER;"); - - } - } - - /* - * Creates an ALTER expression for a column in PostgreSQL - * - * @param $tableName Name of the table to be altered - * @param $colName Name of the column to be altered - * @param $colSpec String which contains conditions for a column - * @return string - */ - private function alterTableAlterColumn($tableName, $colName, $colSpec){ - // First, we split the column specifications into parts - // TODO: this returns an empty array for the following string: int(11) not null auto_increment - // on second thoughts, why is an auto_increment field being passed through? - - $pattern = '/^([\w()]+)\s?((?:not\s)?null)?\s?(default\s[\w\']+)?\s?(check\s[\w()\'",\s]+)?$/i'; - preg_match($pattern, $colSpec, $matches); - - if(sizeof($matches)==0) return ''; - - if($matches[1]=='serial8') return ''; - - if(isset($matches[1])) { - $alterCol = "ALTER COLUMN \"$colName\" TYPE $matches[1]\n"; - - // SET null / not null - if(!empty($matches[2])) { - $alterCol .= ",\nALTER COLUMN \"$colName\" SET $matches[2]"; - } - - // SET default (we drop it first, for reasons of precaution) - if(!empty($matches[3])) { - $alterCol .= ",\nALTER COLUMN \"$colName\" DROP DEFAULT"; - $alterCol .= ",\nALTER COLUMN \"$colName\" SET $matches[3]"; - } - - // SET check constraint (The constraint HAS to be dropped) - $existing_constraint=$this->query("SELECT conname FROM pg_constraint WHERE conname='{$tableName}_{$colName}_check';")->value(); - if(isset($matches[4])) { - //Take this new constraint and see what's outstanding from the target table: - $constraint_bits=explode('(', $matches[4]); - $constraint_values=trim($constraint_bits[2], ')'); - $constraint_values_bits=explode(',', $constraint_values); - $default=trim($constraint_values_bits[0], " '"); - - //Now go and convert anything that's not in this list to 'Page' - //We have to run this as a query, not as part of the alteration queries due to the way they are constructed. - $updateConstraint=''; - $updateConstraint.="UPDATE \"{$tableName}\" SET \"$colName\"='$default' WHERE \"$colName\" NOT IN ($constraint_values);"; - if($this->hasTable("{$tableName}_Live")) { - $updateConstraint.="UPDATE \"{$tableName}_Live\" SET \"$colName\"='$default' WHERE \"$colName\" NOT IN ($constraint_values);"; - } - if($this->hasTable("{$tableName}_versions")) { - $updateConstraint.="UPDATE \"{$tableName}_versions\" SET \"$colName\"='$default' WHERE \"$colName\" NOT IN ($constraint_values);"; - } - - DB::query($updateConstraint); - } - - //First, delete any existing constraint on this column, even if it's no longer an enum - if($existing_constraint) - $alterCol .= ",\nDROP CONSTRAINT \"{$tableName}_{$colName}_check\""; - - //Now create the constraint (if we've asked for one) - if(!empty($matches[4])) - $alterCol .= ",\nADD CONSTRAINT \"{$tableName}_{$colName}_check\" $matches[4]"; - } - - return isset($alterCol) ? $alterCol : ''; - } - - public function renameTable($oldTableName, $newTableName) { - $this->query("ALTER TABLE \"$oldTableName\" RENAME TO \"$newTableName\""); - unset(self::$cached_fieldlists[$oldTableName]); - } - - /** - * 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) { - - $this->runTableCheckCommand("VACUUM FULL ANALYZE \"$tableName\""); - $this->runTableCheckCommand("REINDEX TABLE \"$tableName\""); - return true; - } - - /** - * Helper function used by checkAndRepairTable. - * @param string $sql Query to run. - * @return boolean Returns true no matter what; we're not currently checking the status of the command - */ - protected function runTableCheckCommand($sql) { - $testResults = $this->query($sql); - return true; - } - - 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) { - $this->query("ALTER TABLE \"$tableName\" CHANGE \"$fieldName\" \"$fieldName\" $fieldSpec"); - } - - /** - * Change the database column name of the given field. - * - * @param string $tableName The name of the table 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) { - $fieldList = $this->fieldList($tableName); - if(array_key_exists($oldName, $fieldList)) { - $this->query("ALTER TABLE \"$tableName\" RENAME COLUMN \"$oldName\" TO \"$newName\""); - - //Remove this from the cached list: - unset(self::$cached_fieldlists[$tableName]); - - } - } - - public function fieldList($table) { - //Query from http://www.alberton.info/postgresql_meta_info.html - //This gets us more information than we need, but I've included it all for the moment.... - - //if(!isset(self::$cached_fieldlists[$table])){ - $fields = $this->query("SELECT ordinal_position, column_name, data_type, column_default, is_nullable, character_maximum_length, numeric_precision, numeric_scale FROM information_schema.columns WHERE table_name = '" . $this->addslashes($table) . "' ORDER BY ordinal_position;"); - - $output = array(); - if($fields) foreach($fields as $field) { - - switch($field['data_type']){ - case 'character varying': - //Check to see if there's a constraint attached to this column: - //$constraint=$this->query("SELECT conname,pg_catalog.pg_get_constraintdef(r.oid, true) FROM pg_catalog.pg_constraint r WHERE r.contype = 'c' AND conname='" . $table . '_' . $field['column_name'] . "_check' ORDER BY 1;")->first(); - $constraint=$this->constraintExists($table . '_' . $field['column_name'] . '_check'); - if($constraint){ - //Now we need to break this constraint text into bits so we can see what we have: - //Examples: - //CHECK ("CanEditType"::text = ANY (ARRAY['LoggedInUsers'::character varying, 'OnlyTheseUsers'::character varying, 'Inherit'::character varying]::text[])) - //CHECK ("ClassName"::text = 'PageComment'::text) - - //TODO: replace all this with a regular expression! - $value=$constraint['pg_get_constraintdef']; - $value=substr($value, strpos($value,'=')); - $value=str_replace("''", "'", $value); - - $in_value=false; - $constraints=Array(); - $current_value=''; - for($i=0; $i0){ - //Get the default: - $default=trim(substr($field['column_default'], 0, strpos($field['column_default'], '::')), "'"); - $output[$field['column_name']]=$this->enum(Array('default'=>$default, 'name'=>$field['column_name'], 'enums'=>$constraints)); - } - } else{ - $output[$field['column_name']]='varchar(' . $field['character_maximum_length'] . ')'; - } - break; - - case 'numeric': - $output[$field['column_name']]='decimal(' . $field['numeric_precision'] . ',' . $field['numeric_scale'] . ') default ' . (int)$field['column_default']; - break; - - case 'integer': - $output[$field['column_name']]='integer default ' . (int)$field['column_default']; - break; - - case 'timestamp without time zone': - $output[$field['column_name']]='timestamp'; - break; - - case 'smallint': - $output[$field['column_name']]='smallint default ' . (int)$field['column_default']; - break; - - case 'time without time zone': - $output[$field['column_name']]='time'; - break; - - case 'double precision': - $output[$field['column_name']]='float'; - break; - - default: - $output[$field['column_name']] = $field; - } - - } - - // self::$cached_fieldlists[$table]=$output; - //} - - //return self::$cached_fieldlists[$table]; - - return $output; - } - - /** - * - * This allows the cached values for a table's field list to be erased. - * If $tablename is empty, then the whole cache is erased. - * - * @param string $tableName - * - * @return boolean - */ - function clearCachedFieldlist($tableName=false){ - if($tableName) unset(self::$cached_fieldlists[$tableName]); - else self::$cached_fieldlists=array(); - - return true; - } - - /** - * 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) { - $createIndex=$this->getIndexSqlDefinition($tableName, $indexName, $indexSpec); - if($createIndex!==false) $this->query(); - } - - /* - * 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. - * @see parseIndexSpec() for approximate inverse - */ - public function convertIndexSpec($indexSpec, $asDbValue=false, $table=''){ - - if(!$asDbValue){ - if(is_array($indexSpec)){ - //Here we create a db-specific version of whatever index we need to create. - switch($indexSpec['type']){ - case 'fulltext': - $indexSpec='fulltext (' . $indexSpec['value'] . ')'; - break; - case 'unique': - $indexSpec='unique (' . $indexSpec['value'] . ')'; - break; - case 'hash': - $indexSpec='using hash (' . $indexSpec['value'] . ')'; - break; - case 'index': - //The default index is 'btree', which we'll use by default (below): - default: - $indexSpec='using btree (' . $indexSpec['value'] . ')'; - break; - } - } - } else { - $indexSpec = $this->buildPostgresIndexName($table, $indexSpec); - } - return $indexSpec; - } - - /** - * Splits a spec string safely, considering quoted columns, whitespace, - * and cleaning brackets - * @param string $spec The input index specification - * @return array List of columns in the spec - */ - function explodeColumnString($spec) { - // Remove any leading/trailing brackets and outlying modifiers - // E.g. 'unique (Title, "QuotedColumn");' => 'Title, "QuotedColumn"' - $containedSpec = preg_replace('/(.*\(\s*)|(\s*\).*)/', '', $spec); - - // Split potentially quoted modifiers - // E.g. 'Title, "QuotedColumn"' => array('Title', 'QuotedColumn') - return preg_split('/"?\s*,\s*"?/', trim($containedSpec, '(") ')); - } - - /** - * Builds a properly quoted column list from an array - * @param array $columns List of columns to implode - * @return string A properly quoted list of column names - */ - function implodeColumnList($columns) { - if(empty($columns)) return ''; - return '"' . implode('","', $columns) . '"'; - } - - /** - * Given an index specification in the form of a string ensure that each - * column name is property quoted, stripping brackets and modifiers. - * This index may also be in the form of a "CREATE INDEX..." sql fragment - * @param string $spec The input specification or query. E.g. 'unique (Column1, Column2)' - * @return string The properly quoted column list. E.g. '"Column1", "Column2"' - */ - function quoteColumnSpecString($spec) { - $bits = $this->explodeColumnString($spec); - return $this->implodeColumnList($bits); - } - - /** - * Given an index spec determines the index type - * @param type $spec - * @return string - */ - function determineIndexType($spec) { - // check array spec - if(is_array($spec) && isset($spec['type'])) { - return $spec['type']; - } elseif (!is_array($spec) && preg_match('/(?\w+)\s*\(/', $spec, $matchType)) { - return strtolower($matchType['type']); - } else { - return 'index'; - } - } - - /** - * Converts an array or string index spec into a universally useful array - * @see convertIndexSpec() for approximate inverse - * @param string|array $spec - * @return array The resulting spec array with the required fields name, type, and value - */ - function parseIndexSpec($name, $spec){ - - // Do minimal cleanup on any already parsed spec - if(is_array($spec)) { - $spec['value'] = $this->quoteColumnSpecString($spec['value']); - return $spec; - } - - // Nicely formatted spec! - return array( - 'name' => $name, - 'value' => $this->quoteColumnSpecString($spec), - 'type' => $this->determineIndexType($spec) - ); - } - - protected function getIndexSqlDefinition($tableName, $indexName, $indexSpec, $asDbValue=false) { - - //TODO: create table partition support - //TODO: create clustering options - - //NOTE: it is possible for *_renamed tables to have indexes whose names are not updates - //Therefore, we now check for the existance of indexes before we create them. - //This is techically a bug, since new tables will not be indexed. - - // If requesting the definition rather than the DDL - if($asDbValue) { - $indexName=trim($indexName, '()'); - return $indexName; - } - - // Determine index name - $tableCol = $this->buildPostgresIndexName($tableName, $indexName); - - // Consolidate/Cleanup spec into array format - $indexSpec = $this->parseIndexSpec($indexName, $indexSpec); - - //Misc options first: - $fillfactor = $where = ''; - if (isset($indexSpec['fillfactor'])) { - $fillfactor = 'WITH (FILLFACTOR = ' . $indexSpec['fillfactor'] . ')'; - } - if (isset($indexSpec['where'])) { - $where = 'WHERE ' . $indexSpec['where']; - } - - //create a type-specific index - // NOTE: hash should be removed. This is only here to demonstrate how other indexes can be made - // NOTE: Quote the index name to preserve case sensitivity - switch ($indexSpec['type']) { - case 'fulltext': - // @see fulltext() for the definition of the trigger that ts_$IndexName uses for fulltext searching - $spec = "create index \"$tableCol\" ON \"$tableName\" USING " . $this->default_fts_cluster_method . "(\"ts_" . $indexName . "\") $fillfactor $where"; - break; - - case 'unique': - $spec = "create unique index \"$tableCol\" ON \"$tableName\" (" . $indexSpec['value'] . ") $fillfactor $where"; - break; - - case 'btree': - $spec = "create index \"$tableCol\" ON \"$tableName\" USING btree (" . $indexSpec['value'] . ") $fillfactor $where"; - break; - - case 'hash': - //NOTE: this is not a recommended index type - $spec = "create index \"$tableCol\" ON \"$tableName\" USING hash (" . $indexSpec['value'] . ") $fillfactor $where"; - break; - - case 'index': - //'index' is the same as default, just a normal index with the default type decided by the database. - default: - $spec = "create index \"$tableCol\" ON \"$tableName\" (" . $indexSpec['value'] . ") $fillfactor $where"; - } - return trim($spec) . ';'; - } - - function getDbSqlDefinition($tableName, $indexName, $indexSpec) { - return $this->getIndexSqlDefinition($tableName, $indexName, $indexSpec, true); - } - - /** - * 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) { - $indexSpec = trim($indexSpec); - if($indexSpec[0] != '(') { - list($indexType, $indexFields) = explode(' ',$indexSpec,2); - } else { - $indexFields = $indexSpec; - } - - if(!$indexType) { - $indexType = "index"; - } - - $this->query("DROP INDEX \"$indexName\""); - $this->query("ALTER TABLE \"$tableName\" ADD $indexType \"$indexName\" $indexFields"); - } - - /** - * Given a trigger name attempt to determine the columns upon which it acts - * @param string $triggerName Postgres trigger name - * @return array List of columns - */ - protected function extractTriggerColumns($triggerName) - { - $trigger = DB::query($statement = sprintf( - "SELECT tgargs FROM pg_catalog.pg_trigger WHERE tgname='%s'", $this->addslashes($triggerName) - ))->first(); - - // Option 1: output as a string - if(strpos($trigger['tgargs'],'\000') !== false) { - $argList = explode('\000', $trigger['tgargs']); - array_pop($argList); - - // Option 2: hex-encoded (not sure why this happens, depends on PGSQL config) - } else { - $bytes = str_split($trigger['tgargs'],2); - $argList = array(); - $nextArg = ""; - foreach($bytes as $byte) { - if($byte == "00") { - $argList[] = $nextArg; - $nextArg = ""; - } else { - $nextArg .= chr(hexdec($byte)); - } - } - } - - // Drop first two arguments (trigger name and config name) and implode into nice list - return array_slice($argList, 2); - } - - /** - * Return the list of indexes in a table. - * @param string $table The table name. - * @return array - */ - public function indexList($table) { - - //Retrieve a list of indexes for the specified table - $schema_SQL = pg_escape_string($this->dbConn, $this->schema); - $indexes=DB::query("SELECT tablename, indexname, indexdef FROM pg_catalog.pg_indexes WHERE tablename='" . $this->addslashes($table) . "' AND schemaname = '{$schema_SQL}';"); - - $indexList=Array(); - foreach($indexes as $index) { - // Key for the indexList array. Differs from other DB implementations, which is why - // requireIndex() needed to be overridden - $indexName = $index['indexname']; - - //We don't actually need the entire created command, just a few bits: - $prefix=''; - - //Check for uniques: - if(substr($index['indexdef'], 0, 13)=='CREATE UNIQUE') { - $prefix='unique '; - } - - //check for hashes, btrees etc: - if(strpos(strtolower($index['indexdef']), 'using hash ')!==false) { - $prefix='using hash '; - } - - //TODO: Fix me: btree is the default index type: - //if(strpos(strtolower($index['indexdef']), 'using btree ')!==false) - // $prefix='using btree '; - - if(strpos(strtolower($index['indexdef']), 'using rtree ')!==false) { - $prefix='using rtree '; - } - - // For fulltext indexes we need to extract the columns from another source - if (stristr($index['indexdef'], 'using gin')) { - $prefix = 'fulltext '; - // Extract trigger information from postgres - $triggerName = preg_replace('/^ix_/', 'ts_', $index['indexname']); - $columns = $this->extractTriggerColumns($triggerName); - $columnString = $this->implodeColumnList($columns); - } else { - $columnString = $this->quoteColumnSpecString($index['indexdef']); - } - - $indexList[$indexName]['indexname'] = $index['indexname']; - $indexList[$indexName]['spec'] = "$prefix($columnString)"; - } - - return isset($indexList) ? $indexList : null; - - } - - /** - * Generate the given index in the database, modifying whatever already exists as necessary. + * Utility method to manually set the schema to an alternative + * Check existance & sets search path to the supplied schema name * - * The keys of the array are the names of the index. - * The values of the array can be one of: - * - true: Create a single column index on the field named the same as the index. - * - array('type' => 'index|unique|fulltext', 'value' => 'FieldA, FieldB'): This gives you full - * control over the index. - * - * @param string $table The table name. - * @param string $index The index name. - * @param string|boolean $spec The specification of the index. See requireTable() for more information. + * @param string $name Name of the schema + * @param boolean $create Flag indicating whether the schema should be created + * if it doesn't exist. If $create is false and the schema doesn't exist + * then an error will be raised + * @param int|boolean $errorLevel The level of error reporting to enable for + * the query, or false if no error should be raised + * @return boolean Flag indicating success */ - function requireIndex($table, $index, $spec) { - $newTable = false; - - //DB Abstraction: remove this ===true option as a possibility? - if($spec === true) { - $spec = "(\"$index\")"; - } - - //Indexes specified as arrays cannot be checked with this line: (it flattens out the array) - if(!is_array($spec)) { - $spec = preg_replace('/\s*,\s*/', ',', $spec); - } - - if(!isset($this->tableList[strtolower($table)])) $newTable = true; - - if(!$newTable && !isset($this->indexList[$table])) { - $this->indexList[$table] = $this->indexList($table); - } - - //Fix up the index for database purposes - $index=DB::getConn()->getDbSqlDefinition($table, $index, null, true); - - //Fix the key for database purposes - $index_alt = $this->buildPostgresIndexName($table, $index); - - if(!$newTable) { - if(isset($this->indexList[$table][$index_alt])) { - if(is_array($this->indexList[$table][$index_alt])) { - $array_spec = $this->indexList[$table][$index_alt]['spec']; - } else { - $array_spec = $this->indexList[$table][$index_alt]; + public function setSchema($schema, $create = false, $errorLevel = E_USER_ERROR) { + if(!$this->schemaManager->schemaExists($schema)) { + // Check DB creation permisson + if (!$create) { + if ($errorLevel !== false) { + user_error("Schema $schema does not exist", $errorLevel); } + $this->schema = null; + return false; } + $this->schemaManager->createSchema($schema); } - - if($newTable || !isset($this->indexList[$table][$index_alt])) { - $this->transCreateIndex($table, $index, $spec); - $this->alterationMessage("Index $table.$index: created as " . DB::getConn()->convertIndexSpec($spec),"created"); - } else if($array_spec != DB::getConn()->convertIndexSpec($spec)) { - $this->transAlterIndex($table, $index, $spec); - $spec_msg=DB::getConn()->convertIndexSpec($spec); - $this->alterationMessage("Index $table.$index: changed to $spec_msg (from {$array_spec})","changed"); + $this->setSchemaSearchPath($schema); + $this->schema = $schema; + return true; + } + + /** + * Override the schema search path. Search using the arguments supplied. + * NOTE: The search path is normally set through setSchema() and only + * one schema is selected. The facility to add more than one schema to + * the search path is provided as an advanced PostgreSQL feature for raw + * SQL queries. Sapphire cannot search for datamodel tables in alternate + * schemas, so be wary of using alternate schemas within the ORM environment. + * + * @param string $arg1 First schema to use + * @param string $arg2 Second schema to use + * @param string $argN Nth schema to use + */ + public function setSchemaSearchPath() { + if(func_num_args() == 0) { + user_error('At least one Schema must be supplied to set a search path.', E_USER_ERROR); } - } - - /** - * Returns a list of all the tables in the database. - * Table names will all be in lowercase. - * @return array - */ - public function tableList() { - $schema_SQL = pg_escape_string($this->dbConn, $this->schema); - $tables=array(); - foreach($this->query("SELECT tablename FROM pg_catalog.pg_tables WHERE schemaname = '{$schema_SQL}' AND tablename NOT ILIKE 'pg\\\_%' AND tablename NOT ILIKE 'sql\\\_%'") as $record) { - //$table = strtolower(reset($record)); - $table = reset($record); - $tables[$table] = $table; - } - - //Return an empty array if there's nothing in this database - return $tables; - } - - /** - * Determines if a table exists - * @param string $tableName - * @return boolean - */ - function TableExists($tableName){ - $schema_SQL = pg_escape_string($this->dbConn, $this->schema); - $result=$this->query("SELECT tablename FROM pg_catalog.pg_tables WHERE schemaname = '{$schema_SQL}' AND tablename='" . $this->addslashes($tableName) . "';")->first(); - - return !empty($result); - } - - /** - * Find out what the constraint information is, given a constraint name. - * We also cache this result, so the next time we don't need to do a - * query all over again. - * - * @param string $constraint - */ - function constraintExists($constraint){ - if(!isset(self::$cached_constraints[$constraint])){ - $exists=DB::query("SELECT conname,pg_catalog.pg_get_constraintdef(r.oid, true) FROM pg_catalog.pg_constraint r WHERE r.contype = 'c' AND conname='$constraint' ORDER BY 1;")->first(); - self::$cached_constraints[$constraint]=$exists; - } - - return self::$cached_constraints[$constraint]; - } - - /** - * Return the number of rows affected by the previous operation. - * @return int - */ - public function affectedRows() { - return pg_affected_rows(DB::$lastQuery); - } - - /** - * A function to return the field names and datatypes for the particular table - */ - public function tableDetails($tableName){ - $schema_SQL = pg_escape_string($this->dbConn, $this->schema); - $query="SELECT a.attname as \"Column\", pg_catalog.format_type(a.atttypid, a.atttypmod) as \"Datatype\" FROM pg_catalog.pg_attribute a WHERE a.attnum > 0 AND NOT a.attisdropped AND a.attrelid = ( SELECT c.oid FROM pg_catalog.pg_class c LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace WHERE c.relname ~ '^($tableName)$' AND pg_catalog.pg_table_is_visible(c.oid) AND n.nspname = '{$schema_SQL}');"; - - $result=DB::query($query); - - $table=Array(); - while($row=pg_fetch_assoc($result)){ - $table[]=Array('Column'=>$row['Column'], 'DataType'=>$row['DataType']); - } - - return $table; - } - - /** - * Pass a legit trigger name and it will be dropped - * This assumes that the trigger has been named in a unique fashion - */ - function dropTrigger($triggerName, $tableName){ - $exists=DB::query("SELECT tgname FROM pg_trigger WHERE tgname='$triggerName';")->first(); - if($exists){ - DB::query("DROP trigger $triggerName ON \"$tableName\";"); - } - } - - /** - * This will return the fields that the trigger is monitoring - * @param string $trigger - * - * @return array - */ - function triggerFieldsFromTrigger($trigger){ - - if($trigger){ - $tsvector='tsvector_update_trigger'; - $ts_pos=strpos($trigger, $tsvector); - $details=trim(substr($trigger, $ts_pos+strlen($tsvector)), '();'); - //Now split this into bits: - $bits=explode(',', $details); - - $fields=$bits[2]; - - $field_bits=explode(',', str_replace('"', '', $fields)); - $result=array(); - foreach($field_bits as $field_bit) - $result[]=trim($field_bit); - - return $result; - } else - return false; - } - - /** - * Delete all entries from the table instead of truncating it. - * - * This gives a massive speed improvement compared to using TRUNCATE, with - * the caveat that primary keys are not reset etc. - * - * @see DatabaseAdmin::clearAllData() - * - * @param string $table - */ - public function clearTable($table) { - $this->query('DELETE FROM "'.$table.'";'); - } - - /** - * 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, $asDbValue=false){ - //Annoyingly, we need to do a good ol' fashioned switch here: - ($values['default']) ? $default='1' : $default='0'; - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - if($asDbValue) - return Array('data_type'=>'smallint'); - else { - if($values['arrayValue']!='') - $default=''; - else - $default=' default ' . (int)$values['default']; - - return "smallint{$values['arrayValue']}" . $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){ - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - return "date{$values['arrayValue']}"; - } - - /** - * 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){ - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - // Avoid empty strings being put in the db - if($values['precision'] == '') { - $precision = 1; - } else { - $precision = $values['precision']; - } - - $defaultValue = ''; - if(isset($values['default']) && is_numeric($values['default'])) { - $defaultValue = ' default ' . $values['default']; - } - - if($asDbValue) - return Array('data_type'=>'numeric', 'precision'=>$precision); - else return "decimal($precision){$values['arrayValue']}$defaultValue"; - } - - /** - * Return a enum type-formatted string - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function enum($values){ - //Enums are a bit different. We'll be creating a varchar(255) with a constraint of all the usual enum options. - //NOTE: In this one instance, we are including the table name in the values array - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - if($values['arrayValue']!='') - $default=''; - else - $default=" default '{$values['default']}'"; - - return "varchar(255){$values['arrayValue']}" . $default . " check (\"" . $values['name'] . "\" in ('" . implode('\', \'', $values['enums']) . "'))"; - - } - - /** - * 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){ - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - if($asDbValue) - return Array('data_type'=>'double precision'); - else return "float{$values['arrayValue']}"; - } - - /** - * Return a float type-formatted string cause double is not supported - * - * @params array $values Contains a tokenised list of info about this data type - * @return string - */ - public function double($values, $asDbValue=false){ - return $this->float($values, $asDbValue); - } - - /** - * 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){ - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - if($asDbValue) - return Array('data_type'=>'integer', 'precision'=>'32'); - else { - if($values['arrayValue']!='') - $default=''; - else - $default=' default ' . (int)$values['default']; - - return "integer{$values['arrayValue']}" . $default; - } - } - - /** - * Return a datetime type-formatted string - * For PostgreSQL, we simply return the word 'timestamp', 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){ - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - if($asDbValue) - return Array('data_type'=>'timestamp without time zone'); - else - return "timestamp{$values['arrayValue']}"; - } - - /** - * 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){ - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - if($asDbValue) - return Array('data_type'=>'text'); - else - return "text{$values['arrayValue']}"; - } - - /** - * 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){ - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - return "time{$values['arrayValue']}"; - } - - /** - * 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){ - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - if(!isset($values['precision'])) - $values['precision']=255; - - if($asDbValue) - return Array('data_type'=>'varchar', 'precision'=>$values['precision']); - else - return "varchar({$values['precision']}){$values['arrayValue']}"; - } - - /* - * Return a 4 digit numeric type. MySQL has a proprietary 'Year' type. - * For Postgres, we'll use a 4 digit numeric - */ - public function year($values, $asDbValue=false){ - - if(!isset($values['arrayValue'])) - $values['arrayValue']=''; - - //TODO: the DbValue result does not include the numeric_scale option (ie, the ,0 value in 4,0) - if($asDbValue) - return Array('data_type'=>'decimal', 'precision'=>'4'); - else - return "decimal(4,0){$values['arrayValue']}"; - } - - function escape_character($escape=false){ - if($escape) - return "\\\""; - else - return "\""; - } - - /** - * Create a fulltext search datatype for PostgreSQL - * This will also return a trigger to be applied to this table - * - * @todo: create custom functions to allow weighted searches - * - * @param array $spec - */ - function fulltext($this_index, $tableName, $name){ - //For full text search, we need to create a column for the index - $columns = $this->quoteColumnSpecString($this_index['value']); - - $fulltexts = "\"ts_$name\" tsvector"; - $triggerName = $this->buildPostgresTriggerName($tableName, $name); - $language = $this->get_search_language(); - - $this->dropTrigger($triggerName, $tableName); - $triggers = "CREATE TRIGGER \"$triggerName\" BEFORE INSERT OR UPDATE - ON \"$tableName\" FOR EACH ROW EXECUTE PROCEDURE - tsvector_update_trigger(\"ts_$name\", 'pg_catalog.$language', $columns);"; - - return Array('name' => $name, 'ts_name' => "ts_{$name}", 'fulltexts' => $fulltexts, 'triggers' => $triggers); - } - - /** - * This returns the column which is the primary key for each table - * In Postgres, it is a SERIAL8, which is the equivalent of an auto_increment - * - * @return string - */ - function IdColumn($asDbValue=false){ - if($asDbValue) - return 'bigint'; - else return 'serial8 not null'; - } - - /** - * Returns true if this table exists - */ - function hasTable($tableName) { - $schema_SQL = pg_escape_string($this->dbConn, $this->schema); - $result = $this->query("SELECT tablename FROM pg_catalog.pg_tables WHERE schemaname = '{$schema_SQL}' AND tablename = '" . $this->addslashes($tableName) . "'"); - - if ($result->numRecords() > 0) return true; - else return false; - } - - /** - * Returns the SQL command to get all the tables in this database - */ - function allTablesSQL(){ - $schema_SQL = pg_escape_string($this->dbConn, $this->schema); - return "SELECT table_name FROM information_schema.tables WHERE table_schema='{$schema_SQL}' AND table_type='BASE TABLE';"; - } - - /** - * Return enum values for the given field - * @todo Make a proper implementation - */ - function enumValuesForField($tableName, $fieldName) { - //return array('SiteTree','Page'); - $constraints=$this->constraintExists("{$tableName}_{$fieldName}_check"); - $classes=Array(); - if($constraints) - $classes=$this->EnumValuesFromConstraint($constraints['pg_get_constraintdef']); - - return $classes; - } - - /** - * Get the actual enum fields from the constraint value: - */ - private 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; - } - - /** - * Because NOW() doesn't always work... - * MSSQL, I'm looking at you - * - */ - function now(){ - return 'NOW()'; - } - - /* - * 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 equivilents. - */ - 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 - * Using PHP's addslashes method won't work in MSSQL - */ - function addslashes($value){ - if($this->dbConn) return pg_escape_string($this->dbConn, $value); - else return pg_escape_string($value); - } - - /* - * This changes the index name depending on database requirements. - */ - - function modifyIndex($index, $spec) { - return $index; + $schemas = array_values(func_get_args()); + $this->query("SET search_path TO \"" . implode("\",\"", $schemas) . "\""); } /** @@ -1797,68 +264,70 @@ class PostgreSQLDatabase extends SS_Database { //Fix the keywords to be ts_query compatitble: //Spaces must have pipes //@TODO: properly handle boolean operators here. - $keywords=trim($keywords); - $keywords=str_replace(' ', ' | ', $keywords); - $keywords=str_replace('"', "'", $keywords); + $keywords= trim($keywords); + $keywords= str_replace(' ', ' | ', $keywords); + $keywords= str_replace('"', "'", $keywords); - $keywords = Convert::raw2sql(trim($keywords)); - $htmlEntityKeywords = htmlentities($keywords, ENT_NOQUOTES); + $keywords = $this->quoteString(trim($keywords)); //We can get a list of all the tsvector columns though this query: //We know what tables to search in based on the $classesToSearch variable: - $result=DB::query("SELECT table_name, column_name, data_type FROM information_schema.columns WHERE data_type='tsvector' AND table_name in ('" . implode("', '", $classesToSearch) . "');"); + $classesPlaceholders = DB::placeholders($classesToSearch); + $result = $this->preparedQuery(" + SELECT table_name, column_name, data_type + FROM information_schema.columns + WHERE data_type='tsvector' AND table_name in ($classesPlaceholders);", + $classesToSearch + ); if (!$result->numRecords()) throw new Exception('there are no full text columns to search'); - $tables=Array(); + $tables = array(); + $tableParameters = array(); // Make column selection lists $select = array( 'SiteTree' => array( - "\"ClassName\"", - "\"SiteTree\".\"ID\"", - "\"ParentID\"", - "\"Title\"", - "\"URLSegment\"", - "\"Content\"", - "\"LastEdited\"", - "\"Created\"", - "NULL AS \"Filename\"", - "NULL AS \"Name\"", - "\"CanViewType\"" + '"ClassName"', + '"SiteTree"."ID"', + '"ParentID"', + '"Title"', + '"URLSegment"', + '"Content"', + '"LastEdited"', + '"Created"', + 'NULL AS "Filename"', + 'NULL AS "Name"', + '"CanViewType"' ), 'File' => array( - "\"ClassName\"", - "\"File\".\"ID\"", - "0 AS \"ParentID\"", - "\"Title\"", - "NULL AS \"URLSegment\"", - "\"Content\"", - "\"LastEdited\"", - "\"Created\"", - "\"Filename\"", - "\"Name\"", - "NULL AS \"CanViewType\"" + '"ClassName"', + '"File"."ID"', + '0 AS "ParentID"', + '"Title"', + 'NULL AS "URLSegment"', + '"Content"', + '"LastEdited"', + '"Created"', + '"Filename"', + '"Name"', + 'NULL AS "CanViewType"' ) ); foreach($result as $row){ - if($row['table_name']=='SiteTree') { - $showInSearch="AND \"ShowInSearch\"=1 "; - } elseif($row['table_name']=='File') { - // File.ShowInSearch was added later, keep the database driver backwards compatible - // by checking for its existence first - $fields = $this->fieldList($row['table_name']); - if(array_key_exists('ShowInSearch', $fields)) $showInSearch="AND \"ShowInSearch\"=1 "; - else $showInSearch=''; - } else { - $showInSearch=''; + $conditions = array(); + if($row['table_name'] === 'SiteTree' || $row['table_name'] === 'File') { + $conditions[] = array('"ShowInSearch"' => 1); } - //public function extendedSQL($filter = "", $sort = "", $limit = "", $join = "", $having = ""){ - $where = "\"" . $row['table_name'] . "\".\"" . $row['column_name'] . "\" " . $this->default_fts_search_method . ' q ' . $showInSearch; - $query = DataList::create($row['table_name'])->where($where, '')->dataQuery()->query(); + $method = self::default_fts_search_method(); + $conditions[] = "\"{$row['table_name']}\".\"{$row['column_name']}\" $method q "; + $query = DataObject::get($row['table_name'], $where)->dataQuery()->query(); - $query->addFrom(array('tsearch' => ", to_tsquery('" . $this->get_search_language() . "', '$keywords') AS q")); + // Could parameterise this, but convention is only to to so for where conditions + $query->addFrom(array( + 'tsearch' => ", to_tsquery('" . self::search_language() . "', $keywords) AS q" + )); $query->setSelect(array()); foreach($select[$row['table_name']] as $clause) { @@ -1873,20 +342,20 @@ class PostgreSQLDatabase extends SS_Database { $query->setOrderBy(array()); //Add this query to the collection - $tables[] = $query->sql(); + $tables[] = $query->sql($parameters); + $tableParameters = array_merge($tableParameters, $parameters); } - $limit=$pageLength; - $offset=$start; + $limit = $pageLength; + $offset = $start; - if($keywords) - $orderBy=" ORDER BY $sortBy"; + if($keywords) $orderBy = " ORDER BY $sortBy"; else $orderBy=''; $fullQuery = "SELECT * FROM (" . implode(" UNION ", $tables) . ") AS q1 $orderBy LIMIT $limit OFFSET $offset"; // Get records - $records = DB::query($fullQuery); + $records = $this->preparedQuery($fullQuery, $tableParameters); $totalCount=0; foreach($records as $record){ $objects[] = new $record['ClassName']($record); @@ -1903,10 +372,7 @@ class PostgreSQLDatabase extends SS_Database { return $list; } - /* - * Does this database support transactions? - */ - public function supportsTransactions(){ + public function supportsTransactions() { return $this->supportsTransactions; } @@ -1914,203 +380,53 @@ class PostgreSQLDatabase extends SS_Database { * This is a quick lookup to discover if the database supports particular extensions */ public function supportsExtensions($extensions=Array('partitions', 'tablespaces', 'clustering')){ - if(isset($extensions['partitions'])) - return true; - elseif(isset($extensions['tablespaces'])) - return true; - elseif(isset($extensions['clustering'])) - return true; - else - return false; - } - - /** - * @deprecated 1.0 Use transactionStart() (method required for 2.4.x) - */ - public function startTransaction($transaction_mode=false, $session_characteristics=false){ - $this->transactionStart($transaction_mode, $session_characteristics); + if(isset($extensions['partitions'])) return true; + elseif(isset($extensions['tablespaces'])) return true; + elseif(isset($extensions['clustering'])) return true; + else return false; } - /* - * Start a prepared transaction - * See http://developer.postgresql.org/pgdocs/postgres/sql-set-transaction.html for details on transaction isolation options - */ - public function transactionStart($transaction_mode=false, $session_characteristics=false){ - DB::query('BEGIN;'); + public function transactionStart($transaction_mode = false, $session_characteristics = false){ + $this->query('BEGIN;'); - if($transaction_mode) - DB::query('SET TRANSACTION ' . $transaction_mode . ';'); + if($transaction_mode) { + $this->preparedQuery('SET TRANSACTION ?;', array($transaction_mode)); + } - if($session_characteristics) - DB::query('SET SESSION CHARACTERISTICS AS TRANSACTION ' . $session_characteristics . ';'); + if($session_characteristics) { + $this->preparedQuery('SET SESSION CHARACTERISTICS AS TRANSACTION ?;', array($session_characteristics)); + } } - /* - * Create a savepoint that you can jump back to if you encounter problems - */ public function transactionSavepoint($savepoint){ - DB::query("SAVEPOINT $savepoint;"); + $this->preparedQuery("SAVEPOINT ?;", array($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){ - - if($savepoint) - DB::query("ROLLBACK TO $savepoint;"); - else - DB::query('ROLLBACK;'); - - } - - /** - * @deprecated 1.0 Use transactionEnd() (method required for 2.4.x) - */ - public function endTransaction(){ - $this->transactionEnd(); - } - - /* - * Commit everything inside this transaction so far - */ - public function transactionEnd(){ - DB::query('COMMIT;'); - } - - /* - * Given a tablespace and and location, either create a new one - * or update the existing one - */ - public function createOrReplaceTablespace($name, $location){ - $existing=DB::query("SELECT spcname, spclocation FROM pg_tablespace WHERE spcname='$name';")->first(); - - //NOTE: this location must be empty for this to work - //We can't seem to change the location of the tablespace through any ALTER commands :( - - //If a tablespace with this name exists, but the location has changed, then drop the current one - //if($existing && $location!=$existing['spclocation']) - // DB::query("DROP TABLESPACE $name;"); - - //If this is a new tablespace, or we have dropped the current one: - if(!$existing || ($existing && $location!=$existing['spclocation'])) - DB::query("CREATE TABLESPACE $name LOCATION '$location';"); - - } - - public function createOrReplacePartition($tableName, $partitions, $indexes, $extensions){ - - //We need the plpgsql language to be installed for this to work: - $this->createLanguage('plpgsql'); - - $trigger='CREATE OR REPLACE FUNCTION ' . $tableName . '_insert_trigger() RETURNS TRIGGER AS $$ BEGIN '; - $first=true; - - //Do we need to create a tablespace for this item? - if($extensions && isset($extensions['tablespace'])){ - $this->createOrReplaceTablespace($extensions['tablespace']['name'], $extensions['tablespace']['location']); - $tableSpace=' TABLESPACE ' . $extensions['tablespace']['name']; - } else - $tableSpace=''; - - foreach($partitions as $partition_name=>$partition_value){ - //Check that this child table does not already exist: - if(!$this->TableExists($partition_name)){ - DB::query("CREATE TABLE \"$partition_name\" (CHECK (" . str_replace('NEW.', '', $partition_value) . ")) INHERITS (\"$tableName\")$tableSpace;"); - } else { - //Drop the constraint, we will recreate in in the next line - $existing_constraint=$this->query("SELECT conname FROM pg_constraint WHERE conname='{$partition_name}_pkey';"); - if($existing_constraint){ - DB::query("ALTER TABLE \"$partition_name\" DROP CONSTRAINT \"{$partition_name}_pkey\";"); - } - $this->dropTrigger(strtolower('trigger_' . $tableName . '_insert'), $tableName); - } - - DB::query("ALTER TABLE \"$partition_name\" ADD CONSTRAINT \"{$partition_name}_pkey\" PRIMARY KEY (\"ID\");"); - - if($first){ - $trigger.='IF'; - $first=false; - } else - $trigger.='ELSIF'; - - $trigger.=" ($partition_value) THEN INSERT INTO \"$partition_name\" VALUES (NEW.*);"; - - if($indexes){ - // We need to propogate the indexes through to the child pages. - // Some of this code is duplicated, and could be tidied up - foreach($indexes as $name=>$this_index){ - - if($this_index['type']=='fulltext'){ - $fillfactor=$where=''; - if(isset($this_index['fillfactor'])) - $fillfactor='WITH (FILLFACTOR = ' . $this_index['fillfactor'] . ')'; - if(isset($this_index['where'])) - $where='WHERE ' . $this_index['where']; - - DB::query("CREATE INDEX \"" . $this->buildPostgresIndexName($partition_name, $this_index['name']) . "\" ON \"" . $partition_name . "\" USING " . $this->default_fts_cluster_method . "(\"ts_" . $name . "\") $fillfactor $where"); - $ts_details=$this->fulltext($this_index, $partition_name, $name); - DB::query($ts_details['triggers']); - } else { - - if(is_array($this_index)) - $index_name=$this_index['name']; - else $index_name=trim($this_index, '()'); - - $createIndex=$this->getIndexSqlDefinition($partition_name, $index_name, $this_index); - if($createIndex!==false) - DB::query($createIndex); - } - } - } - - //Lastly, clustering goes here: - if($extensions && isset($extensions['cluster'])){ - DB::query("CLUSTER \"$partition_name\" USING \"{$extensions['cluster']}\";"); - } - } - - $trigger.='ELSE RAISE EXCEPTION \'Value id out of range. Fix the ' . $tableName . '_insert_trigger() function!\'; END IF; RETURN NULL; END; $$ LANGUAGE plpgsql;'; - $trigger.='CREATE TRIGGER trigger_' . $tableName . '_insert BEFORE INSERT ON "' . $tableName . '" FOR EACH ROW EXECUTE PROCEDURE ' . $tableName . '_insert_trigger();'; - - DB::query($trigger); - - } - - /* - * This will create a language if it doesn't already exist. - * This is used by the createOrReplacePartition function, which needs plpgsql - */ - public function createLanguage($language){ - $result=DB::query("SELECT lanname FROM pg_language WHERE lanname='$language';")->first(); - - if(!$result){ - DB::query("CREATE LANGUAGE $language;"); + public function transactionRollback($savepoint = false){ + if($savepoint) { + $this->preparedQuery("ROLLBACK TO ?;", array($savepoint)); + } else { + $this->query('ROLLBACK;'); } } - /** - * 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 transactionEnd($chain = false){ + $this->query('COMMIT;'); + } + + public function comparisonClause($field, $value, $exact = false, $negate = false, $caseSensitive = null, $parameterised = false) { if($exact && $caseSensitive === null) { $comp = ($negate) ? '!=' : '='; } else { $comp = ($caseSensitive === true) ? 'LIKE' : 'ILIKE'; 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); + } } /** @@ -2130,7 +446,11 @@ class PostgreSQLDatabase extends SS_Database { 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); + 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( '/%Y/' => 'YYYY', @@ -2206,88 +526,111 @@ class PostgreSQLDatabase extends SS_Database { return "(FLOOR(EXTRACT(epoch FROM $date1)) - FLOOR(EXTRACT(epoch from $date2)))"; } - /** - * Return a set type-formatted string - * This is used for Multi-enum support, which isn't actually supported by Postgres. - * Throws a user error to show our lack of support, and return an "int", specifically for sapphire - * tests that test multi-enums. This results in a test failure, but not crashing the test run. - * - * @param array $values Contains a tokenised list of info about this data type - * @return string - */ - public function set($values){ - user_error("PostGreSQL does not support multi-enum"); - return "int"; + function now(){ + return 'NOW()'; + } + + function random(){ + return 'RANDOM()'; } /** - * Set the current language for the tsearch functions - * - * @todo: somehow link this to the locale options? - * - * @param string $lang + * Determines the name of the current database to be reported externally + * by substituting the schema name for the database name. + * Should only be used when model_schema_as_database is true + * + * @param string $schema Name of the schema + * @return string Name of the database to report */ - public function set_search_language($lang){ - $this->search_language=$lang; - } - - /** - * Returns the current language for the tsearch functions - * - * @param string $lang - */ - public function get_search_language(){ - return $this->search_language; - } -} - -/** - * A result-set from a PostgreSQL database. - * @package sapphire - * @subpackage model - */ -class PostgreSQLQuery extends SS_Query { - /** - * The MySQLDatabase object that created this result set. - * @var PostgreSQLDatabase - */ - private $database; - - /** - * The internal Postgres handle that points to the result set. - * @var resource - */ - private $handle; - - /** - * Hook the result-set given into a Query class, suitable for use by sapphire. - * @param database The database object that created this query. - * @param handle the internal Postgres handle that is points to the resultset. - */ - public function __construct(PostgreSQLDatabase $database, $handle) { - $this->database = $database; - $this->handle = $handle; - } - - public function __destruct() { - if(is_resource($this->handle)) pg_free_result($this->handle); - } - - public function seek($row) { - return pg_result_seek($this->handle, $row); - } - - public function numRecords() { - return pg_num_rows($this->handle); - } - - public function nextRecord() { - if($data = pg_fetch_assoc($this->handle)) { - return $data; - } else { - return false; + public function schemaToDatabaseName($schema) { + switch($schema) { + case $this->schemaOriginal: return $this->databaseOriginal; + default: return $schema; } } -} + /** + * Translates a requested database name to a schema name to substitute internally. + * Should only be used when model_schema_as_database is true + * + * @param string $database Name of the database + * @return string Name of the schema to use for this database internally + */ + public function databaseToSchemaName($database) { + switch($database) { + case $this->databaseOriginal: return $this->schemaOriginal; + default: return $database; + } + } + public function dropSelectedDatabase() { + if(self::model_schema_as_database()) { + // Check current schema is valid + $oldSchema = $this->schema; + if(empty($oldSchema)) return true; // Nothing selected to drop + + // Select another schema + if($oldSchema !== $this->schemaOriginal) { + $this->setSchema($this->schemaOriginal); + } elseif($oldSchema !== self::MASTER_SCHEMA) { + $this->setSchema(self::MASTER_SCHEMA); + } else { + $this->schema = null; + } + + // Remove this schema + $this->schemaManager->dropSchema($oldSchema); + } else { + parent::dropSelectedDatabase(); + } + } + + public function getSelectedDatabase() { + if(self::model_schema_as_database()) { + return $this->schemaToDatabaseName($this->schema); + } + return parent::getSelectedDatabase(); + } + + public function selectDatabase($name, $create = false, $errorLevel = E_USER_ERROR) { + // Substitute schema here as appropriate + if(self::model_schema_as_database()) { + // Selecting the database itself should be treated as selecting the public schema + $schemaName = $this->databaseToSchemaName($name); + return $this->setSchema($schemaName, $create, $errorLevel); + } + + // Database selection requires that a new connection is established. + // This is not ideal postgres practise + 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); + } + + // New connection made here, treating the new database name as the new original + $this->databaseOriginal = $name; + $this->connectDefault(); + } + + /** + * Delete all entries from the table instead of truncating it. + * + * This gives a massive speed improvement compared to using TRUNCATE, with + * the caveat that primary keys are not reset etc. + * + * @see DatabaseAdmin::clearAllData() + * + * @param string $table + */ + public function clearTable($table) { + $this->query('DELETE FROM "'.$table.'";'); + } +} diff --git a/code/PostgreSQLDatabaseConfigurationHelper.php b/code/PostgreSQLDatabaseConfigurationHelper.php index 53397bd..bbb65d5 100644 --- a/code/PostgreSQLDatabaseConfigurationHelper.php +++ b/code/PostgreSQLDatabaseConfigurationHelper.php @@ -8,71 +8,65 @@ * @package postgresql */ class PostgreSQLDatabaseConfigurationHelper implements DatabaseConfigurationHelper { - + /** - * Ensure that the database function pg_connect - * is available. If it is, we assume the PHP module for this - * database has been setup correctly. + * Create a connection of the appropriate type * - * @param array $databaseConfig Associative array of database configuration, e.g. "server", "username" etc - * @return boolean + * @param array $databaseConfig + * @param string $error Error message passed by value + * @return mixed|null Either the connection object, or null if error */ - public function requireDatabaseFunctions($databaseConfig) { - return (function_exists('pg_connect')) ? true : false; + protected function createConnection($databaseConfig, &$error) { + $error = null; + $username = empty($databaseConfig['username']) ? '' : $databaseConfig['username']; + $password = empty($databaseConfig['password']) ? '' : $databaseConfig['password']; + $server = $databaseConfig['server']; + + try { + switch($databaseConfig['type']) { + case 'PostgreSQLDatabase': + $userPart = $username ? " user=$username" : ''; + $passwordPart = $password ? " password=$password" : ''; + $connstring = "host=$server port=5432 dbname=postgres{$userPart}{$passwordPart}"; + $conn = pg_connect($connstring); + break; + case 'PostgrePDODatabase': + // May throw a PDOException if fails + $conn = @new PDO('postgresql:host='.$server.';dbname=postgres;port=5432', $username, $password); + break; + default: + $error = 'Invalid connection type'; + return null; + } + } catch(Exception $ex) { + $error = $ex->getMessage(); + return null; + } + if($conn) { + return $conn; + } else { + $error = 'PostgreSQL requires a valid username and password to determine if the server exists.'; + return null; + } } - /** - * Ensure that the database server exists. - * @param array $databaseConfig Associative array of db configuration, e.g. "server", "username" etc - * @return array Result - e.g. array('success' => true, 'error' => 'details of error') - */ - public function requireDatabaseServer($databaseConfig) { - $success = false; - $error = ''; - $username = $databaseConfig['username'] ? $databaseConfig['username'] : ''; - $password = $databaseConfig['password'] ? $databaseConfig['password'] : ''; - $server = $databaseConfig['server']; - $userPart = $username ? " user=$username" : ''; - $passwordPart = $password ? " password=$password" : ''; - $connstring = "host=$server port=5432 dbname=postgres {$userPart}{$passwordPart}"; + public function requireDatabaseFunctions($databaseConfig) { + $data = DatabaseAdapterRegistry::get_adapter($databaseConfig['type']); + return !empty($data['supported']); + } - $conn = @pg_connect($connstring); - if($conn) { - $success = true; - } else { - $success = false; - $error = 'PostgreSQL requires a valid username and password to determine if the server exists.'; - } - + public function requireDatabaseServer($databaseConfig) { + $conn = $this->createConnection($databaseConfig, $error); + $success = !empty($conn); return array( 'success' => $success, 'error' => $error ); } - /** - * Ensure a database connection is possible using credentials provided. - * @param array $databaseConfig Associative array of db configuration, e.g. "server", "username" etc - * @return array Result - e.g. array('success' => true, 'error' => 'details of error') - */ public function requireDatabaseConnection($databaseConfig) { - $success = false; - $error = ''; - $username = $databaseConfig['username'] ? $databaseConfig['username'] : ''; - $password = $databaseConfig['password'] ? $databaseConfig['password'] : ''; - $server = $databaseConfig['server']; - $userPart = $username ? " user=$username" : ''; - $passwordPart = $password ? " password=$password" : ''; - $connstring = "host=$server port=5432 dbname=postgres {$userPart}{$passwordPart}"; - - $conn = @pg_connect($connstring); - if($conn) { - $success = true; - } else { - $success = false; - $error = ''; - } - + $conn = $this->createConnection($databaseConfig, $error); + $success = !empty($conn); return array( 'success' => $success, 'connection' => $conn, @@ -81,33 +75,22 @@ class PostgreSQLDatabaseConfigurationHelper implements DatabaseConfigurationHelp } public function getDatabaseVersion($databaseConfig) { - $version = 0; - $username = $databaseConfig['username'] ? $databaseConfig['username'] : ''; - $password = $databaseConfig['password'] ? $databaseConfig['password'] : ''; - $server = $databaseConfig['server']; - $userPart = $username ? " user=$username" : ''; - $passwordPart = $password ? " password=$password" : ''; - $connstring = "host=$server port=5432 dbname=postgres {$userPart}{$passwordPart}"; - $conn = @pg_connect($connstring); - $info = @pg_version($conn); - $version = ($info && isset($info['server'])) ? $info['server'] : null; - if(!$version) { - // fallback to using the version() function - $result = @pg_query($conn, "SELECT version()"); - $row = @pg_fetch_array($result); - - if($row && isset($row[0])) { - $parts = explode(' ', trim($row[0])); - // ASSUMPTION version number is the second part e.g. "PostgreSQL 8.4.3" - $version = trim($parts[1]); - } + $conn = $this->createConnection($databaseConfig, $error); + if(!$conn) { + return false; + } elseif($conn instanceof PDO) { + return $conn->getAttribute(PDO::ATTR_SERVER_VERSION); + } elseif(is_resource($conn)) { + $info = pg_version($conn); + return $info['server']; + } else { + return false; } - - return $version; } /** * Ensure that the PostgreSQL version is at least 8.3. + * * @param array $databaseConfig Associative array of db configuration, e.g. "server", "username" etc * @return array Result - e.g. array('success' => true, 'error' => 'details of error') */ @@ -130,29 +113,60 @@ class PostgreSQLDatabaseConfigurationHelper implements DatabaseConfigurationHelp 'error' => $error ); } - + /** - * Ensure that the database connection is able to use an existing database, - * or be able to create one if it doesn't exist. + * Helper function to quote a string value * - * @param array $databaseConfig Associative array of db configuration, e.g. "server", "username" etc - * @return array Result - e.g. array('success' => true, 'alreadyExists' => 'true') + * @param mixed $conn Connection object/resource + * @param string $value Value to quote + * @return string Quoted strieng */ + protected function quote($conn, $value) { + if($conn instanceof PDO) { + return $conn->quote($value); + } elseif(is_resource($conn)) { + return "'".pg_escape_string($conn, $value)."'"; + } else { + user_error('Invalid database connection', E_USER_ERROR); + } + } + + /** + * Helper function to execute a query + * + * @param mixed $conn Connection object/resource + * @param string $sql SQL string to execute + * @return array List of first value from each resulting row + */ + protected function query($conn, $sql) { + $items = array(); + if($conn instanceof PDO) { + foreach($conn->query($sql) as $row) { + $items[] = $row[0]; + } + } elseif(is_resource($conn)) { + $result = pg_query($conn, $sql); + while ($row = pg_fetch_row($result)) { + $items[] = $row[0]; + } + } + return $items; + } + public function requireDatabaseOrCreatePermissions($databaseConfig) { $success = false; $alreadyExists = false; - $check = $this->requireDatabaseConnection($databaseConfig); - $conn = $check['connection']; - - $result = pg_query($conn, "SELECT datname FROM pg_database WHERE datname = '$databaseConfig[database]'"); - if(pg_fetch_array($result)) { - $success = true; - $alreadyExists = true; - } else { - if(@pg_query($conn, "CREATE DATABASE testing123")) { - pg_query($conn, "DROP DATABASE testing123"); + $conn = $this->createConnection($databaseConfig, $error); + if($conn) { + // Check if db already exists + $existingDatabases = $this->query($conn, "SELECT datname FROM pg_database"); + $alreadyExists = in_array($databaseConfig['database'], $existingDatabases); + if($alreadyExists) { $success = true; - $alreadyExists = false; + } else { + // Check if this user has create privileges + $allowedUsers = $this->query($conn, "select rolname from pg_authid where rolcreatedb = true;"); + $success = in_array($databaseConfig['username'], $allowedUsers); } } @@ -161,16 +175,19 @@ class PostgreSQLDatabaseConfigurationHelper implements DatabaseConfigurationHelp 'alreadyExists' => $alreadyExists ); } - - /** - * 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); + $success = false; + $conn = $this->createConnection($databaseConfig, $error); + if($conn) { + // Check if this user has create privileges on the default tablespace + $sqlUsername = $this->quote($conn, $databaseConfig['username']); + $permissions = $this->query($conn, "select * from has_tablespace_privilege($sqlUsername, 'pg_default', 'create')"); + $success = $permissions && (reset($permissions) == 't'); + } + return array( + 'success' => $success, + 'applies' => true + ); } - } diff --git a/code/PostgreSQLQuery.php b/code/PostgreSQLQuery.php new file mode 100644 index 0000000..f51d686 --- /dev/null +++ b/code/PostgreSQLQuery.php @@ -0,0 +1,41 @@ +handle = $handle; + } + + public function __destruct() { + if(is_resource($this->handle)) pg_free_result($this->handle); + } + + public function seek($row) { + return pg_result_seek($this->handle, $row); + } + + public function numRecords() { + return pg_num_rows($this->handle); + } + + public function nextRecord() { + return pg_fetch_assoc($this->handle); + } +} diff --git a/code/PostgreSQLSchemaManager.php b/code/PostgreSQLSchemaManager.php new file mode 100644 index 0000000..f9c41be --- /dev/null +++ b/code/PostgreSQLSchemaManager.php @@ -0,0 +1,1445 @@ +buildPostgresIndexName($table, $index); + } + + /** + * Creates a postgres database, ignoring model_schema_as_database + * + * @param string $name + */ + public function createPostgresDatabase($name) { + $this->query("CREATE DATABASE \"$name\";"); + } + + public function createDatabase($name) { + if(PostgreSQLDatabase::model_schema_as_database()) { + $schemaName = $this->database->databaseToSchemaName($name); + return $this->createSchema($schemaName); + } + return $this->createPostgresDatabase($name); + } + + /** + * Determines if a postgres database exists, ignoring model_schema_as_database + * + * @param string $name + * @return boolean + */ + public function postgresDatabaseExists($name) { + $result = $this->preparedQuery("SELECT datname FROM pg_database WHERE datname = ?;", array($name)); + return $result->first() ? true : false; + } + + public function databaseExists($name) { + if(PostgreSQLDatabase::model_schema_as_database()) { + $schemaName = $this->database->databaseToSchemaName($name); + return $this->schemaExists($schemaName); + } + return $this->postgresDatabaseExists($name); + } + + /** + * Determines the list of all postgres databases, ignoring model_schema_as_database + * + * @return array + */ + public function postgresDatabaseList() { + return $this->query("SELECT datname FROM pg_database WHERE datistemplate=false;")->column(); + } + + public function databaseList() { + if(PostgreSQLDatabase::model_schema_as_database()) { + $schemas = $this->schemaList(); + $names = array(); + foreach($schemas as $schema) { + $names[] = $this->database->schemaToDatabaseName($schema); + } + return array_unique($names); + } + return $this->postgresDatabaseList(); + } + /** + * Drops a postgres database, ignoring model_schema_as_database + * + * @param string $name + */ + public function dropPostgresDatabase($name) { + $nameSQL = $this->database->escapeIdentifier($name); + $this->query("DROP DATABASE $nameSQL;"); + } + + public function dropDatabase($name) { + if(PostgreSQLDatabase::model_schema_as_database()) { + $schemaName = $this->database->databaseToSchemaName($name); + return $this->dropSchema($schemaName); + } + $this->dropPostgresDatabase($name); + } + + /** + * Returns true if the schema exists in the current database + * + * @param string $name + * @return boolean + */ + public function schemaExists($name) { + return $this->preparedQuery( + "SELECT nspname FROM pg_catalog.pg_namespace WHERE nspname = ?;", + array($name) + )->first() ? true : false; + } + + /** + * Creates a schema in the current database + * + * @param string $name + */ + public function createSchema($name) { + $nameSQL = $this->database->escapeIdentifier($name); + $this->query("CREATE SCHEMA $nameSQL;"); + } + + /** + * Drops a schema from the database. Use carefully! + * + * @param string $name + */ + public function dropSchema($name) { + $nameSQL = $this->database->escapeIdentifier($name); + $this->query("DROP SCHEMA $nameSQL CASCADE;"); + } + + /** + * Returns the list of all available schemas on the current database + * + * @return array + */ + public function schemaList() { + return $this->query(" + SELECT nspname + FROM pg_catalog.pg_namespace + WHERE nspname <> 'information_schema' AND nspname !~ E'^pg_'" + )->column(); + } + + public function createTable($table, $fields = null, $indexes = null, $options = null, $advancedOptions = null) { + + $fieldSchemas = $indexSchemas = ""; + if($fields) foreach($fields as $k => $v) { + $fieldSchemas .= "\"$k\" $v,\n"; + } + if(!empty($options[self::ID])) { + $addOptions = $options[self::ID]; + } elseif (!empty($options[get_class($this)])) { + Deprecation::notice('3.2', 'Use PostgreSQLSchemaManager::ID for referencing postgres-specific table creation options'); + $addOptions = $options[get_class($this)]; + } else { + $addOptions = null; + } + + //First of all, does this table already exist + $doesExist = $this->hasTable($table); + if($doesExist) { + // Table already exists, just return the name, in line with baseclass documentation. + return $table; + } + + //If we have a fulltext search request, then we need to create a special column + //for GiST searches + $fulltexts = ''; + $triggers = ''; + if($indexes) { + foreach($indexes as $name => $this_index){ + if(is_array($this_index) && $this_index['type'] == 'fulltext') { + $ts_details = $this->fulltext($this_index, $table, $name); + $fulltexts .= $ts_details['fulltexts'] . ', '; + $triggers .= $ts_details['triggers']; + } + } + } + + if($indexes) foreach($indexes as $k => $v) { + $indexSchemas .= $this->getIndexSqlDefinition($table, $k, $v) . "\n"; + } + + //Do we need to create a tablespace for this item? + if($advancedOptions && isset($advancedOptions['tablespace'])){ + $this->createOrReplaceTablespace( + $advancedOptions['tablespace']['name'], + $advancedOptions['tablespace']['location'] + ); + $tableSpace = ' TABLESPACE ' . $advancedOptions['tablespace']['name']; + } else + $tableSpace = ''; + + $this->query("CREATE TABLE \"$table\" ( + $fieldSchemas + $fulltexts + primary key (\"ID\") + )$tableSpace; $indexSchemas $addOptions"); + + if($triggers!=''){ + $this->query($triggers); + } + + //If we have a partitioning requirement, we do that here: + if($advancedOptions && isset($advancedOptions['partitions'])){ + $this->createOrReplacePartition($table, $advancedOptions['partitions'], $indexes, $advancedOptions); + } + + //Lastly, clustering goes here: + if($advancedOptions && isset($advancedOptions['cluster'])){ + $this->query("CLUSTER \"$table\" USING \"{$advancedOptions['cluster']}\";"); + } + + return $table; + } + + /** + * Builds the internal Postgres index name given the silverstripe table and index name + * + * @param string $tableName + * @param string $indexName + * @param string $prefix The optional prefix for the index. Defaults to "ix" for indexes. + * @return string The postgres name of the index + */ + protected function buildPostgresIndexName($tableName, $indexName, $prefix = 'ix') { + + // Assume all indexes also contain the table name + // MD5 the table/index name combo to keep it to a fixed length. + // Exclude the prefix so that the trigger name can be easily generated from the index name + $indexNamePG = "{$prefix}_" . md5("{$tableName}_{$indexName}"); + + // Limit to 63 characters + if (strlen($indexNamePG) > 63) { + return substr($indexNamePG, 0, 63); + } else { + return $indexNamePG; + } + } + + /** + * Builds the internal Postgres trigger name given the silverstripe table and trigger name + * + * @param string $tableName + * @param string $triggerName + * @return string The postgres name of the trigger + */ + function buildPostgresTriggerName($tableName, $triggerName) { + // Kind of cheating, but behaves the same way as indexes + return $this->buildPostgresIndexName($tableName, $triggerName, 'ts'); + } + + public function alterTable($table, $newFields = null, $newIndexes = null, $alteredFields = null, $alteredIndexes = null, $alteredOptions = null, $advancedOptions = null) { + + $alterList = array(); + if($newFields) foreach($newFields as $fieldName => $fieldSpec) { + $alterList[] = "ADD \"$fieldName\" $fieldSpec"; + } + + if ($alteredFields) foreach ($alteredFields as $indexName => $indexSpec) { + $val = $this->alterTableAlterColumn($table, $indexName, $indexSpec); + if (!empty($val)) $alterList[] = $val; + } + + //Do we need to do anything with the tablespaces? + if($alteredOptions && isset($advancedOptions['tablespace'])){ + $this->createOrReplaceTablespace($advancedOptions['tablespace']['name'], $advancedOptions['tablespace']['location']); + $this->query("ALTER TABLE \"$table\" SET TABLESPACE {$advancedOptions['tablespace']['name']};"); + } + + //DB ABSTRACTION: we need to change the constraints to be a separate 'add' command, + //see http://www.postgresql.org/docs/8.1/static/sql-altertable.html + $alterIndexList = array(); + //Pick up the altered indexes here: + $fieldList = $this->fieldList($table); + $fulltexts = false; + $drop_triggers = false; + $triggers = false; + if($alteredIndexes) foreach($alteredIndexes as $indexName=>$indexSpec) { + + $indexSpec = $this->parseIndexSpec($indexName, $indexSpec); + $indexNamePG = $this->buildPostgresIndexName($table, $indexName); + + if($indexSpec['type']=='fulltext') { + //For full text indexes, we need to drop the trigger, drop the index, AND drop the column + + //Go and get the tsearch details: + $ts_details = $this->fulltext($indexSpec, $table, $indexName); + + //Drop this column if it already exists: + + //No IF EXISTS option is available for Postgres <9.0 + if(array_key_exists($ts_details['ts_name'], $fieldList)){ + $fulltexts.="ALTER TABLE \"{$table}\" DROP COLUMN \"{$ts_details['ts_name']}\";"; + } + + // We'll execute these later: + $triggerNamePG = $this->buildPostgresTriggerName($table, $indexName); + $drop_triggers.= "DROP TRIGGER IF EXISTS \"$triggerNamePG\" ON \"$table\";"; + $fulltexts .= "ALTER TABLE \"{$table}\" ADD COLUMN {$ts_details['fulltexts']};"; + $triggers .= $ts_details['triggers']; + } + + // Create index action (including fulltext) + $alterIndexList[] = "DROP INDEX IF EXISTS \"$indexNamePG\";"; + $createIndex = $this->getIndexSqlDefinition($table, $indexName, $indexSpec); + if($createIndex!==false) $alterIndexList[] = $createIndex; + } + + //Add the new indexes: + if($newIndexes) foreach($newIndexes as $indexName => $indexSpec){ + + $indexSpec = $this->parseIndexSpec($indexName, $indexSpec); + $indexNamePG = $this->buildPostgresIndexName($table, $indexName); + //If we have a fulltext search request, then we need to create a special column + //for GiST searches + //Pick up the new indexes here: + if($indexSpec['type']=='fulltext') { + $ts_details=$this->fulltext($indexSpec, $table, $indexName); + if(!isset($fieldList[$ts_details['ts_name']])){ + $fulltexts.="ALTER TABLE \"{$table}\" ADD COLUMN {$ts_details['fulltexts']};"; + $triggers.=$ts_details['triggers']; + } + } + + //Check that this index doesn't already exist: + $indexes=$this->indexList($table); + if(isset($indexes[$indexName])){ + $alterIndexList[] = "DROP INDEX IF EXISTS \"$indexNamePG\";"; + } + + $createIndex=$this->getIndexSqlDefinition($table, $indexName, $indexSpec); + if($createIndex!==false) + $alterIndexList[] = $createIndex; + } + + if($alterList) { + $alterations = implode(",\n", $alterList); + $this->query("ALTER TABLE \"$table\" " . $alterations); + } + + //Do we need to create a tablespace for this item? + if($advancedOptions && isset($advancedOptions['extensions']['tablespace'])){ + $extensions=$advancedOptions['extensions']; + $this->createOrReplaceTablespace($extensions['tablespace']['name'], $extensions['tablespace']['location']); + } + + if($alteredOptions && isset($this->class) && isset($alteredOptions[$this->class])) { + $this->query(sprintf("ALTER TABLE \"%s\" %s", $table, $alteredOptions[$this->class])); + Database::alteration_message( + sprintf("Table %s options changed: %s", $table, $alteredOptions[$this->class]), + "changed" + ); + } + + //Create any fulltext columns and triggers here: + if($fulltexts) $this->query($fulltexts); + if($drop_triggers) $this->query($drop_triggers); + + if($triggers) { + $this->query($triggers); + + $triggerbits=explode(';', $triggers); + foreach($triggerbits as $trigger){ + $trigger_fields=$this->triggerFieldsFromTrigger($trigger); + + if($trigger_fields){ + //We need to run a simple query to force the database to update the triggered columns + $this->query("UPDATE \"{$table}\" SET \"{$trigger_fields[0]}\"=\"$trigger_fields[0]\";"); + } + } + } + + foreach($alterIndexList as $alteration) $this->query($alteration); + + //If we have a partitioning requirement, we do that here: + if($advancedOptions && isset($advancedOptions['partitions'])){ + $this->createOrReplacePartition($table, $advancedOptions['partitions']); + } + + //Lastly, clustering goes here: + if ($advancedOptions && isset($advancedOptions['cluster'])) { + $clusterIndex = $this->buildPostgresIndexName($table, $advancedOptions['cluster']); + $this->query("CLUSTER \"$table\" USING \"$clusterIndex\";"); + } else { + //Check that clustering is not on this table, and if it is, remove it: + + //This is really annoying. We need the oid of this table: + $stats = $this->preparedQuery( + "SELECT relid FROM pg_stat_user_tables WHERE relname = ?;", + array($table) + )->first(); + $oid=$stats['relid']; + + //Now we can run a long query to get the clustered status: + //If anyone knows a better way to get the clustered status, then feel free to replace this! + $clustered = $this->preparedQuery(" + SELECT c2.relname, i.indisclustered + FROM pg_catalog.pg_class c, pg_catalog.pg_class c2, pg_catalog.pg_index i + WHERE c.oid = ? AND c.oid = i.indrelid AND i.indexrelid = c2.oid AND indisclustered='t';", + array($oid) + )->first(); + + if($clustered) { + $this->query("ALTER TABLE \"$table\" SET WITHOUT CLUSTER;"); + } + } + } + + /* + * Creates an ALTER expression for a column in PostgreSQL + * + * @param $tableName Name of the table to be altered + * @param $colName Name of the column to be altered + * @param $colSpec String which contains conditions for a column + * @return string + */ + private function alterTableAlterColumn($tableName, $colName, $colSpec){ + // First, we split the column specifications into parts + // TODO: this returns an empty array for the following string: int(11) not null auto_increment + // on second thoughts, why is an auto_increment field being passed through? + + $pattern = '/^([\w()]+)\s?((?:not\s)?null)?\s?(default\s[\w\']+)?\s?(check\s[\w()\'",\s]+)?$/i'; + preg_match($pattern, $colSpec, $matches); + + if(sizeof($matches)==0) return ''; + + if($matches[1]=='serial8') return ''; + + if(isset($matches[1])) { + $alterCol = "ALTER COLUMN \"$colName\" TYPE $matches[1]\n"; + + // SET null / not null + if(!empty($matches[2])) { + $alterCol .= ",\nALTER COLUMN \"$colName\" SET $matches[2]"; + } + + // SET default (we drop it first, for reasons of precaution) + if(!empty($matches[3])) { + $alterCol .= ",\nALTER COLUMN \"$colName\" DROP DEFAULT"; + $alterCol .= ",\nALTER COLUMN \"$colName\" SET $matches[3]"; + } + + // SET check constraint (The constraint HAS to be dropped) + $existing_constraint=$this->query("SELECT conname FROM pg_constraint WHERE conname='{$tableName}_{$colName}_check';")->value(); + if(isset($matches[4])) { + //Take this new constraint and see what's outstanding from the target table: + $constraint_bits=explode('(', $matches[4]); + $constraint_values=trim($constraint_bits[2], ')'); + $constraint_values_bits=explode(',', $constraint_values); + $default=trim($constraint_values_bits[0], " '"); + + //Now go and convert anything that's not in this list to 'Page' + //We have to run this as a query, not as part of the alteration queries due to the way they are constructed. + $updateConstraint=''; + $updateConstraint.="UPDATE \"{$tableName}\" SET \"$colName\"='$default' WHERE \"$colName\" NOT IN ($constraint_values);"; + if($this->hasTable("{$tableName}_Live")) { + $updateConstraint.="UPDATE \"{$tableName}_Live\" SET \"$colName\"='$default' WHERE \"$colName\" NOT IN ($constraint_values);"; + } + if($this->hasTable("{$tableName}_versions")) { + $updateConstraint.="UPDATE \"{$tableName}_versions\" SET \"$colName\"='$default' WHERE \"$colName\" NOT IN ($constraint_values);"; + } + + $this->query($updateConstraint); + } + + //First, delete any existing constraint on this column, even if it's no longer an enum + if($existing_constraint) { + $alterCol .= ",\nDROP CONSTRAINT \"{$tableName}_{$colName}_check\""; + } + + //Now create the constraint (if we've asked for one) + if(!empty($matches[4])) { + $alterCol .= ",\nADD CONSTRAINT \"{$tableName}_{$colName}_check\" $matches[4]"; + } + } + + return isset($alterCol) ? $alterCol : ''; + } + + public function renameTable($oldTableName, $newTableName) { + $this->query("ALTER TABLE \"$oldTableName\" RENAME TO \"$newTableName\""); + unset(self::$cached_fieldlists[$oldTableName]); + } + + public function checkAndRepairTable($tableName) { + $this->query("VACUUM FULL ANALYZE \"$tableName\""); + $this->query("REINDEX TABLE \"$tableName\""); + return true; + } + + 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) { + $this->query("ALTER TABLE \"$tableName\" CHANGE \"$fieldName\" \"$fieldName\" $fieldSpec"); + } + + public function renameField($tableName, $oldName, $newName) { + $fieldList = $this->fieldList($tableName); + if(array_key_exists($oldName, $fieldList)) { + $this->query("ALTER TABLE \"$tableName\" RENAME COLUMN \"$oldName\" TO \"$newName\""); + + //Remove this from the cached list: + unset(self::$cached_fieldlists[$tableName]); + } + } + + public function fieldList($table) { + //Query from http://www.alberton.info/postgresql_meta_info.html + //This gets us more information than we need, but I've included it all for the moment.... + + //if(!isset(self::$cached_fieldlists[$table])){ + $fields = $this->preparedQuery(" + SELECT ordinal_position, column_name, data_type, column_default, + is_nullable, character_maximum_length, numeric_precision, numeric_scale + FROM information_schema.columns WHERE table_name = ? + ORDER BY ordinal_position;", + array($table) + ); + + $output = array(); + if($fields) foreach($fields as $field) { + + switch($field['data_type']){ + case 'character varying': + //Check to see if there's a constraint attached to this column: + //$constraint=$this->query("SELECT conname,pg_catalog.pg_get_constraintdef(r.oid, true) FROM pg_catalog.pg_constraint r WHERE r.contype = 'c' AND conname='" . $table . '_' . $field['column_name'] . "_check' ORDER BY 1;")->first(); + $constraint = $this->constraintExists($table . '_' . $field['column_name'] . '_check'); + if($constraint){ + //Now we need to break this constraint text into bits so we can see what we have: + //Examples: + //CHECK ("CanEditType"::text = ANY (ARRAY['LoggedInUsers'::character varying, 'OnlyTheseUsers'::character varying, 'Inherit'::character varying]::text[])) + //CHECK ("ClassName"::text = 'PageComment'::text) + + //TODO: replace all this with a regular expression! + $value=$constraint['pg_get_constraintdef']; + $value=substr($value, strpos($value,'=')); + $value=str_replace("''", "'", $value); + + $in_value=false; + $constraints=Array(); + $current_value=''; + for($i=0; $i0){ + //Get the default: + $default=trim(substr($field['column_default'], 0, strpos($field['column_default'], '::')), "'"); + $output[$field['column_name']]=$this->enum(Array('default'=>$default, 'name'=>$field['column_name'], 'enums'=>$constraints)); + } + } else{ + $output[$field['column_name']]='varchar(' . $field['character_maximum_length'] . ')'; + } + break; + + case 'numeric': + $output[$field['column_name']]='decimal(' . $field['numeric_precision'] . ',' . $field['numeric_scale'] . ') default ' . (int)$field['column_default']; + break; + + case 'integer': + $output[$field['column_name']]='integer default ' . (int)$field['column_default']; + break; + + case 'timestamp without time zone': + $output[$field['column_name']]='timestamp'; + break; + + case 'smallint': + $output[$field['column_name']]='smallint default ' . (int)$field['column_default']; + break; + + case 'time without time zone': + $output[$field['column_name']]='time'; + break; + + case 'double precision': + $output[$field['column_name']]='float'; + break; + + default: + $output[$field['column_name']] = $field; + } + + } + + // self::$cached_fieldlists[$table]=$output; + //} + + //return self::$cached_fieldlists[$table]; + + return $output; + } + + function clearCachedFieldlist($tableName=false){ + if($tableName) unset(self::$cached_fieldlists[$tableName]); + else self::$cached_fieldlists=array(); + return true; + } + + /** + * 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) { + $createIndex = $this->getIndexSqlDefinition($tableName, $indexName, $indexSpec); + if($createIndex !== false) $this->query($createIndex); + } + + /* + * @todo - factor out? Is DBSchemaManager::convertIndexSpec sufficient? + public function convertIndexSpec($indexSpec, $asDbValue=false, $table=''){ + + if(!$asDbValue){ + if(is_array($indexSpec)){ + //Here we create a db-specific version of whatever index we need to create. + switch($indexSpec['type']){ + case 'fulltext': + $indexSpec='fulltext (' . $indexSpec['value'] . ')'; + break; + case 'unique': + $indexSpec='unique (' . $indexSpec['value'] . ')'; + break; + case 'hash': + $indexSpec='using hash (' . $indexSpec['value'] . ')'; + break; + case 'index': + //The default index is 'btree', which we'll use by default (below): + default: + $indexSpec='using btree (' . $indexSpec['value'] . ')'; + break; + } + } + } else { + $indexSpec = $this->buildPostgresIndexName($table, $indexSpec); + } + return $indexSpec; + }*/ + + protected function getIndexSqlDefinition($tableName, $indexName, $indexSpec, $asDbValue=false) { + + //TODO: create table partition support + //TODO: create clustering options + + //NOTE: it is possible for *_renamed tables to have indexes whose names are not updates + //Therefore, we now check for the existance of indexes before we create them. + //This is techically a bug, since new tables will not be indexed. + + // If requesting the definition rather than the DDL + if($asDbValue) { + $indexName=trim($indexName, '()'); + return $indexName; + } + + // Determine index name + $tableCol = $this->buildPostgresIndexName($tableName, $indexName); + + // Consolidate/Cleanup spec into array format + $indexSpec = $this->parseIndexSpec($indexName, $indexSpec); + + //Misc options first: + $fillfactor = $where = ''; + if (isset($indexSpec['fillfactor'])) { + $fillfactor = 'WITH (FILLFACTOR = ' . $indexSpec['fillfactor'] . ')'; + } + if (isset($indexSpec['where'])) { + $where = 'WHERE ' . $indexSpec['where']; + } + + //create a type-specific index + // NOTE: hash should be removed. This is only here to demonstrate how other indexes can be made + // NOTE: Quote the index name to preserve case sensitivity + switch ($indexSpec['type']) { + case 'fulltext': + // @see fulltext() for the definition of the trigger that ts_$IndexName uses for fulltext searching + $clusterMethod = PostgreSQLDatabase::default_fts_cluster_method(); + $spec = "create index \"$tableCol\" ON \"$tableName\" USING $clusterMethod(\"ts_" . $indexName . "\") $fillfactor $where"; + break; + + case 'unique': + $spec = "create unique index \"$tableCol\" ON \"$tableName\" (" . $indexSpec['value'] . ") $fillfactor $where"; + break; + + case 'btree': + $spec = "create index \"$tableCol\" ON \"$tableName\" USING btree (" . $indexSpec['value'] . ") $fillfactor $where"; + break; + + case 'hash': + //NOTE: this is not a recommended index type + $spec = "create index \"$tableCol\" ON \"$tableName\" USING hash (" . $indexSpec['value'] . ") $fillfactor $where"; + break; + + case 'index': + //'index' is the same as default, just a normal index with the default type decided by the database. + default: + $spec = "create index \"$tableCol\" ON \"$tableName\" (" . $indexSpec['value'] . ") $fillfactor $where"; + } + return trim($spec) . ';'; + } + + public function alterIndex($tableName, $indexName, $indexSpec) { + $indexSpec = trim($indexSpec); + if($indexSpec[0] != '(') { + list($indexType, $indexFields) = explode(' ',$indexSpec,2); + } else { + $indexFields = $indexSpec; + } + + if(!$indexType) { + $indexType = "index"; + } + + $this->query("DROP INDEX \"$indexName\""); + $this->query("ALTER TABLE \"$tableName\" ADD $indexType \"$indexName\" $indexFields"); + } + + /** + * Given a trigger name attempt to determine the columns upon which it acts + * + * @param string $triggerName Postgres trigger name + * @return array List of columns + */ + protected function extractTriggerColumns($triggerName) + { + $trigger = $this->preparedQuery( + "SELECT tgargs FROM pg_catalog.pg_trigger WHERE tgname = ?", + array($triggerName) + )->first(); + + // Option 1: output as a string + if(strpos($trigger['tgargs'],'\000') !== false) { + $argList = explode('\000', $trigger['tgargs']); + array_pop($argList); + + // Option 2: hex-encoded (not sure why this happens, depends on PGSQL config) + } else { + $bytes = str_split($trigger['tgargs'],2); + $argList = array(); + $nextArg = ""; + foreach($bytes as $byte) { + if($byte == "00") { + $argList[] = $nextArg; + $nextArg = ""; + } else { + $nextArg .= chr(hexdec($byte)); + } + } + } + + // Drop first two arguments (trigger name and config name) and implode into nice list + return array_slice($argList, 2); + } + + public function indexList($table) { + //Retrieve a list of indexes for the specified table + $indexes = $this->preparedQuery(" + SELECT tablename, indexname, indexdef + FROM pg_catalog.pg_indexes + WHERE tablename = ? AND schemaname = ?;", + array($table, $this->database->currentSchema()) + ); + + $indexList = array(); + foreach($indexes as $index) { + // Key for the indexList array. Differs from other DB implementations, which is why + // requireIndex() needed to be overridden + $indexName = $index['indexname']; + + //We don't actually need the entire created command, just a few bits: + $type = ''; + + //Check for uniques: + if(substr($index['indexdef'], 0, 13)=='CREATE UNIQUE') { + $type = 'unique'; + } + + //check for hashes, btrees etc: + if(strpos(strtolower($index['indexdef']), 'using hash ')!==false) { + $type = 'hash'; + } + + //TODO: Fix me: btree is the default index type: + //if(strpos(strtolower($index['indexdef']), 'using btree ')!==false) + // $prefix='using btree '; + + if(strpos(strtolower($index['indexdef']), 'using rtree ')!==false) { + $type = 'rtree'; + } + + // For fulltext indexes we need to extract the columns from another source + if (stristr($index['indexdef'], 'using gin')) { + $type = 'fulltext'; + // Extract trigger information from postgres + $triggerName = preg_replace('/^ix_/', 'ts_', $index['indexname']); + $columns = $this->extractTriggerColumns($triggerName); + $columnString = $this->implodeColumnList($columns); + } else { + $columnString = $this->quoteColumnSpecString($index['indexdef']); + } + + $indexList[$indexName] = $this->parseIndexSpec($index, array( + 'name' => $indexName, // Not the correct name in the PHP, as this will be a mangled postgres-unique code + 'value' => $columnString, + 'type' => $type + )); + } + + return $indexList; + + } + + public function tableList() { + $tables = array(); + $result = $this->preparedQuery( + "SELECT tablename FROM pg_catalog.pg_tables WHERE schemaname = ? AND tablename NOT ILIKE 'pg\\\_%' AND tablename NOT ILIKE 'sql\\\_%'", + array($this->database->currentSchema()) + ); + foreach($result as $record) { + $table = reset($record); + $tables[strtolower($table)] = $table; + } + return $tables; + } + + /** + * Find out what the constraint information is, given a constraint name. + * We also cache this result, so the next time we don't need to do a + * query all over again. + * + * @param string $constraint + */ + function constraintExists($constraint){ + if(!isset(self::$cached_constraints[$constraint])){ + $exists = $this->preparedQuery(" + SELECT conname,pg_catalog.pg_get_constraintdef(r.oid, true) + FROM pg_catalog.pg_constraint r WHERE r.contype = 'c' AND conname = ? ORDER BY 1;", + array($constraint) + )->first(); + self::$cached_constraints[$constraint]=$exists; + } + + return self::$cached_constraints[$constraint]; + } + + /** + * A function to return the field names and datatypes for the particular table + * + * @param string $tableName + * @return array List of columns an an associative array with the keys Column and DataType + */ + public function tableDetails($tableName) { + $query = "SELECT a.attname as \"Column\", pg_catalog.format_type(a.atttypid, a.atttypmod) as \"Datatype\" + FROM pg_catalog.pg_attribute a + WHERE a.attnum > 0 AND NOT a.attisdropped AND a.attrelid = ( + SELECT c.oid + FROM pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + WHERE c.relname = ? AND pg_catalog.pg_table_is_visible(c.oid) AND n.nspname = ? + );"; + + $result = $this->preparedQuery($query, $tableName, $this->database->currentSchema()); + + $table = array(); + while($row = pg_fetch_assoc($result)) { + $table[] = array( + 'Column' => $row['Column'], + 'DataType' => $row['DataType'] + ); + } + + return $table; + } + + /** + * Pass a legit trigger name and it will be dropped + * This assumes that the trigger has been named in a unique fashion + * + * @param string $triggerName Name of the trigger + * @param string $tableName Name of the table + */ + function dropTrigger($triggerName, $tableName){ + $exists = $this->preparedQuery(" + SELECT trigger_name + FROM information_schema.triggers + WHERE trigger_name = ? AND trigger_schema = ?;", + array($triggerName, $this->database->currentSchema()) + )->first(); + if($exists){ + $this->query("DROP trigger IF EXISTS $triggerName ON \"$tableName\";"); + } + } + + /** + * This will return the fields that the trigger is monitoring + * + * @param string $trigger Name of the trigger + * @return array + */ + function triggerFieldsFromTrigger($trigger) { + + if($trigger){ + $tsvector='tsvector_update_trigger'; + $ts_pos=strpos($trigger, $tsvector); + $details=trim(substr($trigger, $ts_pos+strlen($tsvector)), '();'); + //Now split this into bits: + $bits=explode(',', $details); + + $fields=$bits[2]; + + $field_bits=explode(',', str_replace('"', '', $fields)); + $result=array(); + foreach($field_bits as $field_bit) + $result[]=trim($field_bit); + + return $result; + } else { + return false; + } + } + + /** + * Return a boolean type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function boolean($values, $asDbValue=false){ + //Annoyingly, we need to do a good ol' fashioned switch here: + $default = $values['default'] ? '1' : '0'; + + if(!isset($values['arrayValue'])) { + $values['arrayValue']=''; + } + + if($asDbValue) { + return array('data_type'=>'smallint'); + } + + if($values['arrayValue'] != '') { + $default = ''; + } else { + $default = ' default ' . (int)$values['default']; + } + return "smallint{$values['arrayValue']}" . $default; + } + + /** + * Return a date type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @return string + */ + public function date($values){ + + if(!isset($values['arrayValue'])) { + $values['arrayValue']=''; + } + + return "date{$values['arrayValue']}"; + } + + /** + * Return a decimal type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function decimal($values, $asDbValue=false){ + + if(!isset($values['arrayValue'])) { + $values['arrayValue']=''; + } + + // Avoid empty strings being put in the db + if($values['precision'] == '') { + $precision = 1; + } else { + $precision = $values['precision']; + } + + $defaultValue = ''; + if(isset($values['default']) && is_numeric($values['default'])) { + $defaultValue = ' default ' . $values['default']; + } + + if($asDbValue) { + return array('data_type' => 'numeric', 'precision' => $precision); + } else { + return "decimal($precision){$values['arrayValue']}$defaultValue"; + } + } + + /** + * Return a enum type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @return string + */ + public function enum($values){ + //Enums are a bit different. We'll be creating a varchar(255) with a constraint of all the usual enum options. + //NOTE: In this one instance, we are including the table name in the values array + if(!isset($values['arrayValue'])) { + $values['arrayValue']=''; + } + + if($values['arrayValue']!='') { + $default = ''; + } else { + $default = " default '{$values['default']}'"; + } + + return "varchar(255){$values['arrayValue']}" . $default . " check (\"" . $values['name'] . "\" in ('" . implode('\', \'', $values['enums']) . "'))"; + + } + + /** + * Return a float type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function float($values, $asDbValue = false){ + if(!isset($values['arrayValue'])) { + $values['arrayValue']=''; + } + + if($asDbValue) { + return array('data_type' => 'double precision'); + } else { + return "float{$values['arrayValue']}"; + } + } + + /** + * Return a float type-formatted string cause double is not supported + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function double($values, $asDbValue=false){ + return $this->float($values, $asDbValue); + } + + /** + * Return a int type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function int($values, $asDbValue = false){ + + if(!isset($values['arrayValue'])) { + $values['arrayValue']=''; + } + + if($asDbValue) { + return Array('data_type'=>'integer', 'precision'=>'32'); + } + + if($values['arrayValue']!='') { + $default=''; + } else { + $default=' default ' . (int)$values['default']; + } + + return "integer{$values['arrayValue']}" . $default; + } + + /** + * Return a datetime type-formatted string + * For PostgreSQL, we simply return the word 'timestamp', no other parameters are necessary + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function SS_Datetime($values, $asDbValue = false){ + + if(!isset($values['arrayValue'])) { + $values['arrayValue']=''; + } + + if($asDbValue) { + return array('data_type'=>'timestamp without time zone'); + } else { + return "timestamp{$values['arrayValue']}"; + } + } + + /** + * Return a text type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function text($values, $asDbValue = false){ + + if(!isset($values['arrayValue'])) { + $values['arrayValue'] = ''; + } + + if($asDbValue) { + return array('data_type'=>'text'); + } else { + return "text{$values['arrayValue']}"; + } + } + + /** + * Return a time type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @return string + */ + public function time($values){ + if(!isset($values['arrayValue'])) { + $values['arrayValue'] = ''; + } + + return "time{$values['arrayValue']}"; + } + + /** + * Return a varchar type-formatted string + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function varchar($values, $asDbValue=false){ + + if(!isset($values['arrayValue'])) { + $values['arrayValue'] = ''; + } + + if(!isset($values['precision'])) { + $values['precision'] = 255; + } + + if($asDbValue) { + return array('data_type'=>'varchar', 'precision'=>$values['precision']); + } else { + return "varchar({$values['precision']}){$values['arrayValue']}"; + } + } + + /* + * Return a 4 digit numeric type. MySQL has a proprietary 'Year' type. + * For Postgres, we'll use a 4 digit numeric + * + * @param array $values Contains a tokenised list of info about this data type + * @param boolean $asDbValue + * @return string + */ + public function year($values, $asDbValue = false){ + + if(!isset($values['arrayValue'])) { + $values['arrayValue'] = ''; + } + + //TODO: the DbValue result does not include the numeric_scale option (ie, the ,0 value in 4,0) + if($asDbValue) { + return array('data_type'=>'decimal', 'precision'=>'4'); + } else { + return "decimal(4,0){$values['arrayValue']}"; + } + } + + /** + * Create a fulltext search datatype for PostgreSQL + * This will also return a trigger to be applied to this table + * + * @todo: create custom functions to allow weighted searches + * + * @param array $this_index Index specification for the fulltext index + * @param string $tableName + * @param string $name + * @param array $spec + */ + function fulltext($this_index, $tableName, $name){ + //For full text search, we need to create a column for the index + $columns = $this->quoteColumnSpecString($this_index['value']); + + $fulltexts = "\"ts_$name\" tsvector"; + $triggerName = $this->buildPostgresTriggerName($tableName, $name); + $language = PostgreSQLDatabase::search_language(); + + $this->dropTrigger($triggerName, $tableName); + $triggers = "CREATE TRIGGER \"$triggerName\" BEFORE INSERT OR UPDATE + ON \"$tableName\" FOR EACH ROW EXECUTE PROCEDURE + tsvector_update_trigger(\"ts_$name\", 'pg_catalog.$language', $columns);"; + + return array( + 'name' => $name, + 'ts_name' => "ts_{$name}", + 'fulltexts' => $fulltexts, + 'triggers' => $triggers + ); + } + + function IdColumn($asDbValue = false, $hasAutoIncPK = true){ + if($asDbValue) return 'bigint'; + else return 'serial8 not null'; + } + + public function hasTable($tableName) { + $result = $this->preparedQuery( + "SELECT tablename FROM pg_catalog.pg_tables WHERE schemaname = ? AND tablename = ?;", + array($this->database->currentSchema(), $tableName) + ); + return ($result->numRecords() > 0); + } + + /** + * Returns the values of the given enum field + * + * @todo Make a proper implementation + * + * @param string $tableName Name of table to check + * @param string $fieldName name of enum field to check + * @return array List of enum values + */ + function enumValuesForField($tableName, $fieldName) { + //return array('SiteTree','Page'); + $constraints = $this->constraintExists("{$tableName}_{$fieldName}_check"); + if($constraints) { + return $this->enumValuesFromConstraint($constraints['pg_get_constraintdef']); + } else { + return array(); + } + } + + function dbDataType($type){ + $values = array( + 'unsigned integer' => 'INT' + ); + + if(isset($values[$type])) return $values[$type]; + else return ''; + } + + /* + * Given a tablespace and and location, either create a new one + * or update the existing one + * + * @param string $name + * @param string $location + */ + public function createOrReplaceTablespace($name, $location){ + $existing = $this->preparedQuery( + "SELECT spcname, spclocation FROM pg_tablespace WHERE spcname = ?;", + array($name) + )->first(); + + //NOTE: this location must be empty for this to work + //We can't seem to change the location of the tablespace through any ALTER commands :( + + //If a tablespace with this name exists, but the location has changed, then drop the current one + //if($existing && $location!=$existing['spclocation']) + // DB::query("DROP TABLESPACE $name;"); + + //If this is a new tablespace, or we have dropped the current one: + if(!$existing || ($existing && $location != $existing['spclocation'])) { + $this->query("CREATE TABLESPACE $name LOCATION '$location';"); + } + } + + /** + * + * @param string $tableName + * @param array $partitions + * @param array $indexes + * @param array $extensions + */ + public function createOrReplacePartition($tableName, $partitions, $indexes, $extensions){ + + //We need the plpgsql language to be installed for this to work: + $this->createLanguage('plpgsql'); + + $trigger='CREATE OR REPLACE FUNCTION ' . $tableName . '_insert_trigger() RETURNS TRIGGER AS $$ BEGIN '; + $first=true; + + //Do we need to create a tablespace for this item? + if($extensions && isset($extensions['tablespace'])){ + $this->createOrReplaceTablespace($extensions['tablespace']['name'], $extensions['tablespace']['location']); + $tableSpace=' TABLESPACE ' . $extensions['tablespace']['name']; + } else { + $tableSpace=''; + } + + foreach($partitions as $partition_name => $partition_value){ + //Check that this child table does not already exist: + if(!$this->hasTable($partition_name)){ + $this->query("CREATE TABLE \"$partition_name\" (CHECK (" . str_replace('NEW.', '', $partition_value) . ")) INHERITS (\"$tableName\")$tableSpace;"); + } else { + //Drop the constraint, we will recreate in in the next line + $existing_constraint = $this->preparedQuery( + "SELECT conname FROM pg_constraint WHERE conname = ?;", + array("{$partition_name}_pkey") + ); + if($existing_constraint){ + $this->query("ALTER TABLE \"$partition_name\" DROP CONSTRAINT \"{$partition_name}_pkey\";"); + } + $this->dropTrigger(strtolower('trigger_' . $tableName . '_insert'), $tableName); + } + + $this->query("ALTER TABLE \"$partition_name\" ADD CONSTRAINT \"{$partition_name}_pkey\" PRIMARY KEY (\"ID\");"); + + if($first){ + $trigger.='IF'; + $first=false; + } else { + $trigger.='ELSIF'; + } + + $trigger .= " ($partition_value) THEN INSERT INTO \"$partition_name\" VALUES (NEW.*);"; + + if($indexes){ + // We need to propogate the indexes through to the child pages. + // Some of this code is duplicated, and could be tidied up + foreach($indexes as $name => $this_index){ + + if($this_index['type']=='fulltext'){ + $fillfactor = $where = ''; + if(isset($this_index['fillfactor'])) { + $fillfactor = 'WITH (FILLFACTOR = ' . $this_index['fillfactor'] . ')'; + } + if(isset($this_index['where'])) { + $where = 'WHERE ' . $this_index['where']; + } + $clusterMethod = PostgreSQLDatabase::default_fts_cluster_method(); + $this->query("CREATE INDEX \"" . $this->buildPostgresIndexName($partition_name, $this_index['name']) . "\" ON \"" . $partition_name . "\" USING $clusterMethod(\"ts_" . $name . "\") $fillfactor $where"); + $ts_details = $this->fulltext($this_index, $partition_name, $name); + $this->query($ts_details['triggers']); + } else { + + if(is_array($this_index)) { + $index_name = $this_index['name']; + } else { + $index_name = trim($this_index, '()'); + } + + $createIndex = $this->getIndexSqlDefinition($partition_name, $index_name, $this_index); + if($createIndex !== false) { + $this->query($createIndex); + } + } + } + } + + //Lastly, clustering goes here: + if($extensions && isset($extensions['cluster'])){ + $this->query("CLUSTER \"$partition_name\" USING \"{$extensions['cluster']}\";"); + } + } + + $trigger .= 'ELSE RAISE EXCEPTION \'Value id out of range. Fix the ' . $tableName . '_insert_trigger() function!\'; END IF; RETURN NULL; END; $$ LANGUAGE plpgsql;'; + $trigger .= 'CREATE TRIGGER trigger_' . $tableName . '_insert BEFORE INSERT ON "' . $tableName . '" FOR EACH ROW EXECUTE PROCEDURE ' . $tableName . '_insert_trigger();'; + + $this->query($trigger); + } + + /* + * This will create a language if it doesn't already exist. + * This is used by the createOrReplacePartition function, which needs plpgsql + * + * @param string $language Language name + */ + public function createLanguage($language){ + $result = $this->preparedQuery( + "SELECT lanname FROM pg_language WHERE lanname = ?;", + array($language) + )->first(); + + if(!$result) { + $this->query("CREATE LANGUAGE $language;"); + } + } + + /** + * Return a set type-formatted string + * This is used for Multi-enum support, which isn't actually supported by Postgres. + * Throws a user error to show our lack of support, and return an "int", specifically for sapphire + * tests that test multi-enums. This results in a test failure, but not crashing the test run. + * + * @param array $values Contains a tokenised list of info about this data type + * @return string + */ + public function set($values){ + user_error("PostGreSQL does not support multi-enum", E_USER_ERROR); + return "int"; + } +} diff --git a/docs/README.md b/docs/README.md index 44501c2..1276517 100644 --- a/docs/README.md +++ b/docs/README.md @@ -180,10 +180,10 @@ Please consult the official Postgres documentation for more information. Transactions are supported at the database connection level. The relevant functions are: -* DB::getConn()→startTransaction($transaction_mode, $session_characteristics) -* DB::getConn()→transactionSavepoint($name) -* DB::getConn()→transactionRollback($savepoint) -* DB::getConn()→endTransaction(); +* DB::get_conn()→startTransaction($transaction_mode, $session_characteristics) +* DB::get_conn()→transactionSavepoint($name) +* DB::get_conn()→transactionRollback($savepoint) +* DB::get_conn()→endTransaction(); You can create a savepoint by passing a name to the function, and then rollback either all of the uncommited transactions, or if you pass a savepoint name, diff --git a/docs/en/README.md b/docs/en/README.md index 44501c2..1276517 100644 --- a/docs/en/README.md +++ b/docs/en/README.md @@ -180,10 +180,10 @@ Please consult the official Postgres documentation for more information. Transactions are supported at the database connection level. The relevant functions are: -* DB::getConn()→startTransaction($transaction_mode, $session_characteristics) -* DB::getConn()→transactionSavepoint($name) -* DB::getConn()→transactionRollback($savepoint) -* DB::getConn()→endTransaction(); +* DB::get_conn()→startTransaction($transaction_mode, $session_characteristics) +* DB::get_conn()→transactionSavepoint($name) +* DB::get_conn()→transactionRollback($savepoint) +* DB::get_conn()→endTransaction(); You can create a savepoint by passing a name to the function, and then rollback either all of the uncommited transactions, or if you pass a savepoint name, diff --git a/tests/PostgreSQLConnectorTest.php b/tests/PostgreSQLConnectorTest.php new file mode 100644 index 0000000..18642d6 --- /dev/null +++ b/tests/PostgreSQLConnectorTest.php @@ -0,0 +1,49 @@ +assertEquals( + "SELECT * FROM Table WHERE ID = $1", + $connector->replacePlaceholders("SELECT * FROM Table WHERE ID = ?") + ); + + // Multiple variables + $this->assertEquals( + "SELECT * FROM Table WHERE ID = $1 AND Name = $2", + $connector->replacePlaceholders("SELECT * FROM Table WHERE ID = ? AND Name = ?") + ); + + // Ignoring question mark placeholders within string literals + $this->assertEquals( + "SELECT * FROM Table WHERE ID = $1 AND Name = $2 AND Content = '

What is love?

'", + $connector->replacePlaceholders( + "SELECT * FROM Table WHERE ID = ? AND Name = ? AND Content = '

What is love?

'" + ) + ); + + // Ignoring question mark placeholders within string literals with escaped slashes + $this->assertEquals( + "SELECT * FROM Table WHERE ID = $1 AND Title = '\\'' AND Name = $2 AND Content = '

What is love?

'", + $connector->replacePlaceholders( + "SELECT * FROM Table WHERE ID = ? AND Title = '\\'' AND Name = ? AND Content = '

What is love?

'" + ) + ); + + // same as above, but use double single quote escape syntax + $this->assertEquals( + "SELECT * FROM Table WHERE ID = $1 AND Title = '''' AND Name = $2 AND Content = '

What is love?

'", + $connector->replacePlaceholders( + "SELECT * FROM Table WHERE ID = ? AND Title = '''' AND Name = ? AND Content = '

What is love?

'" + ) + ); + } +} diff --git a/tests/PostgreSQLDatabaseTest.php b/tests/PostgreSQLDatabaseTest.php index 6c65184..8f6fc69 100644 --- a/tests/PostgreSQLDatabaseTest.php +++ b/tests/PostgreSQLDatabaseTest.php @@ -7,15 +7,15 @@ class PostgreSQLDatabaseTest extends SapphireTest { function testReadOnlyTransaction(){ if( - DB::getConn()->supportsTransactions() == true - && DB::getConn() instanceof PostgreSQLDatabase + DB::get_conn()->supportsTransactions() == true + && DB::get_conn() instanceof PostgreSQLDatabase ){ $page=new Page(); $page->Title='Read only success'; $page->write(); - DB::getConn()->transactionStart('READ ONLY'); + DB::get_conn()->transactionStart('READ ONLY'); try { $page=new Page(); @@ -24,10 +24,10 @@ class PostgreSQLDatabaseTest extends SapphireTest { } catch (Exception $e) { //could not write this record //We need to do a rollback or a commit otherwise we'll get error messages - DB::getConn()->transactionRollback(); + DB::get_conn()->transactionRollback(); } - DB::getConn()->transactionEnd(); + DB::get_conn()->transactionEnd(); DataObject::flush_and_destroy_cache(); @@ -45,4 +45,4 @@ class PostgreSQLDatabaseTest extends SapphireTest { } } -} \ No newline at end of file +}