2008-11-23 02:20:39 +01:00
< ? php
/**
* @ package sapphire
* @ subpackage model
*/
/**
* PostgreSQL connector class .
* @ package sapphire
* @ subpackage model
*/
class PostgreSQLDatabase extends Database {
/**
* Connection to the DBMS .
* @ var resource
*/
private $dbConn ;
/**
* True if we are connected to a database .
* @ var boolean
*/
private $active ;
/**
* The name of the database .
* @ var string
*/
private $database ;
2009-09-16 05:51:38 +02:00
/*
* This holds the name of the original database
* So if you switch to another for unit tests , you
* can then switch back in order to drop the temp database
*/
private $database_original ;
2009-09-29 22:59:45 +02:00
/*
* This holds the parameters that the original connection was created with ,
* so we can switch back to it if necessary ( used for unit tests )
*/
2009-09-16 05:51:38 +02:00
private $parameters ;
2009-09-29 22:59:45 +02:00
/*
* 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 = '@@@' ;
2008-11-23 02:20:39 +01:00
/**
* 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 ) {
2009-09-16 05:51:38 +02:00
//We will store these connection parameters for use elsewhere (ie, unit tests)
$this -> parameters = $parameters ;
$this -> connectDatabase ();
$this -> database_original = $this -> database ;
}
/*
* Uses whatever connection details are in the $parameters array to connect to a database of a given name
*/
function connectDatabase (){
$parameters = $this -> parameters ;
if ( ! $parameters )
return false ;
2008-11-23 02:20:39 +01:00
( $parameters [ 'username' ] != '' ) ? $username = ' user=' . $parameters [ 'username' ] : $username = '' ;
( $parameters [ 'password' ] != '' ) ? $password = ' password=' . $parameters [ 'password' ] : $password = '' ;
2009-09-16 05:51:38 +02:00
if ( ! isset ( $this -> database ))
$dbName = $parameters [ 'database' ];
else $dbName = $this -> database ;
2008-11-23 02:20:39 +01:00
//assumes that the server and dbname will always be provided:
2009-09-16 05:51:38 +02:00
$this -> dbConn = pg_connect ( 'host=' . $parameters [ 'server' ] . ' port=5432 dbname=' . $dbName . $username . $password );
2008-11-23 02:20:39 +01:00
//By virtue of getting here, the connection is active:
$this -> active = true ;
2009-09-16 05:51:38 +02:00
$this -> database = $dbName ;
2008-11-23 02:20:39 +01:00
if ( ! $this -> dbConn ) {
$this -> databaseError ( " Couldn't connect to PostgreSQL database " );
2009-09-16 05:51:38 +02:00
return false ;
2008-11-23 02:20:39 +01:00
}
2009-09-16 05:51:38 +02:00
return true ;
2008-11-23 02:20:39 +01:00
}
/**
* Not implemented , needed for PDO
*/
public function getConnect ( $parameters ) {
return null ;
}
/**
* Returns true if this database supports collations
2009-09-16 05:51:38 +02:00
* TODO : get rid of this ?
2008-11-23 02:20:39 +01:00
* @ return boolean
*/
public function supportsCollations () {
2009-09-16 05:51:38 +02:00
return true ;
2008-11-23 02:20:39 +01:00
}
/**
2009-09-16 05:51:38 +02:00
* The version of PostgreSQL .
2008-11-23 02:20:39 +01:00
* @ var float
*/
private $pgsqlVersion ;
/**
* Get the version of MySQL .
* @ return float
*/
public function getVersion () {
if ( ! $this -> pgsqlVersion ) {
//returns something like this: PostgreSQL 8.3.3 on i386-apple-darwin9.3.0, compiled by GCC i686-apple-darwin9-gcc-4.0.1 (GCC) 4.0.1 (Apple Inc. build 5465)
$postgres = strlen ( 'PostgreSQL ' );
$db_version = $this -> query ( " SELECT VERSION() " ) -> value ();
$this -> pgsqlVersion = ( float ) trim ( substr ( $db_version , $postgres , strpos ( $db_version , ' on ' )));
}
return $this -> pgsqlVersion ;
}
/**
2009-09-16 05:51:38 +02:00
* Get the database server , namely PostgreSQL .
2008-11-23 02:20:39 +01:00
* @ return string
*/
public function getDatabaseServer () {
return " postgresql " ;
}
public function query ( $sql , $errorLevel = E_USER_ERROR ) {
2009-09-16 05:51:38 +02:00
2008-11-23 02:20:39 +01:00
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 );
}
2009-09-17 02:10:30 +02:00
2008-11-23 02:20:39 +01:00
$handle = pg_query ( $this -> dbConn , $sql );
if ( isset ( $_REQUEST [ 'showqueries' ])) {
$endtime = round ( microtime ( true ) - $starttime , 4 );
Debug :: message ( " \n $sql\n { $endtime } ms \n " , false );
}
DB :: $lastQuery = $handle ;
2009-09-16 05:51:38 +02:00
if ( ! $handle && $errorLevel ) $this -> databaseError ( " Couldn't run query: $sql | " . pg_last_error ( $this -> dbConn ), $errorLevel );
2009-03-03 22:46:27 +01:00
2008-11-23 02:20:39 +01:00
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 ;
}
2009-09-16 05:51:38 +02:00
/*
* This will create a database based on whatever is in the $this -> database value
* So you need to have called $this -> selectDatabase () first , or used the __construct method
*/
2008-11-23 02:20:39 +01:00
public function createDatabase () {
2009-09-16 05:51:38 +02:00
2008-11-23 02:20:39 +01:00
$this -> query ( " CREATE DATABASE $this->database " );
2009-09-16 05:51:38 +02:00
$this -> connectDatabase ();
2008-11-23 02:20:39 +01:00
}
/**
* Drop the database that this object is currently connected to .
* Use with caution .
*/
public function dropDatabase () {
2009-09-16 05:51:38 +02:00
//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 -> connectDatabase ();
$this -> query ( " DROP DATABASE $db_to_drop " );
2008-11-23 02:20:39 +01:00
}
/**
* 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 ) {
2009-09-16 05:51:38 +02:00
//$this->database = $dbname;
//if($this->databaseExists($this->database)) mysql_select_db($this->database, $this->dbConn);
//if($this->databaseExists($this->database)) pg_d
$this -> database = $dbname ;
2008-11-23 02:20:39 +01:00
$this -> tableList = $this -> fieldList = $this -> indexList = null ;
2009-09-16 05:51:38 +02:00
return true ;
2008-11-23 02:20:39 +01:00
}
2009-09-16 05:51:38 +02:00
2008-11-23 02:20:39 +01:00
/**
* Returns true if the named database exists .
*/
public function databaseExists ( $name ) {
2009-09-16 05:51:38 +02:00
$SQL_name = Convert :: raw2sql ( $name );
$result = $this -> query ( " SELECT datname FROM pg_database WHERE datname=' $SQL_name '; " ) -> first ();
return $this -> query ( " SELECT datname FROM pg_database WHERE datname=' $SQL_name '; " ) -> first () ? true : false ;
2008-11-23 02:20:39 +01:00
}
2009-05-19 23:47:48 +02:00
public function createTable ( $tableName , $fields = null , $indexes = null , $options = null ) {
2008-11-23 02:20:39 +01:00
$fieldSchemas = $indexSchemas = " " ;
if ( $fields ) foreach ( $fields as $k => $v ) $fieldSchemas .= " \" $k\ " $v , \n " ;
2009-09-16 05:51:38 +02:00
if ( isset ( $this -> class )){
$addOptions = ( isset ( $options [ $this -> class ])) ? $options [ $this -> class ] : null ;
} else $addOptions = null ;
2008-11-23 02:20:39 +01:00
2009-09-16 05:51:38 +02:00
//First of all, does this table already exist
$doesExist = $this -> TableExists ( $tableName );
if ( $doesExist )
return false ;
2009-02-13 03:46:54 +01:00
//If we have a fulltext search request, then we need to create a special column
//for GiST searches
2008-11-23 02:20:39 +01:00
$fulltexts = '' ;
2009-09-16 05:51:38 +02:00
$triggers = '' ;
2009-09-29 22:59:45 +02:00
if ( $indexes ){
foreach ( $indexes as $name => $this_index ){
if ( $this_index [ 'type' ] == 'fulltext' ){
//For full text search, we need to create a column for the index
$columns = explode ( ',' , $this_index [ 'value' ]);
for ( $i = 0 ; $i < sizeof ( $columns ); $i ++ )
$columns [ $i ] = " \" " . trim ( $columns [ $i ]) . " \" " ;
$columns = implode ( ', ' , $columns );
$fulltexts .= " \" ts_ $name\ " tsvector , " ;
$triggerName = " ts_ { $tableName } _ { $name } " ;
$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.english' , $columns ); " ;
}
2008-11-23 02:20:39 +01:00
}
}
if ( $indexes ) foreach ( $indexes as $k => $v ) $indexSchemas .= $this -> getIndexSqlDefinition ( $tableName , $k , $v ) . " \n " ;
$this -> query ( " CREATE TABLE \" $tableName\ " (
$fieldSchemas
$fulltexts
primary key ( \ " ID \" )
2009-05-19 23:47:48 +02:00
); $indexSchemas $addOptions " );
2009-09-16 05:51:38 +02:00
if ( $triggers != '' ){
$this -> query ( $triggers );
}
2009-09-29 22:59:45 +02:00
return $tableName ;
2008-11-23 02:20:39 +01:00
}
/**
* 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
*/
2009-05-19 23:47:48 +02:00
public function alterTable ( $tableName , $newFields = null , $newIndexes = null , $alteredFields = null , $alteredIndexes = null , $alteredOptions = null ) {
2008-11-23 02:20:39 +01:00
$fieldSchemas = $indexSchemas = " " ;
2008-11-24 00:29:09 +01:00
$alterList = array ();
2008-11-23 02:20:39 +01:00
if ( $newFields ) foreach ( $newFields as $k => $v ) $alterList [] .= " ADD \" $k\ " $v " ;
2009-02-13 03:46:54 +01:00
if ( $alteredFields ) {
foreach ( $alteredFields as $k => $v ) {
$val = $this -> alterTableAlterColumn ( $tableName , $k , $v );
if ( $val != '' )
$alterList [] .= $val ;
}
}
2008-11-24 00:29:09 +01:00
2008-11-23 02:20:39 +01:00
//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
2009-03-04 22:55:40 +01:00
$alterIndexList = Array ();
if ( $alteredIndexes ) foreach ( $alteredIndexes as $v ) {
2009-09-16 05:51:38 +02:00
//We are only going to delete indexes which exist
$indexes = $this -> indexList ( $tableName );
if ( isset ( $indexes [ $v [ 'value' ]])){
if ( is_array ( $v ))
$alterIndexList [] = 'DROP INDEX ix_' . strtolower ( $tableName ) . '_' . strtolower ( $v [ 'value' ]) . ';' ;
else
$alterIndexList [] = 'DROP INDEX ix_' . strtolower ( $tableName ) . '_' . strtolower ( trim ( $v , '()' )) . ';' ;
$k = $v [ 'value' ];
$alterIndexList [] .= $this -> getIndexSqlDefinition ( $tableName , $k , $v );
}
2008-11-23 02:20:39 +01:00
}
2008-11-24 00:29:09 +01:00
2009-04-06 01:20:09 +02:00
//Add the new indexes:
2009-09-16 05:51:38 +02:00
if ( $newIndexes ) foreach ( $newIndexes as $k => $v ){
//Check that this index doesn't already exist:
$indexes = $this -> indexList ( $tableName );
if ( isset ( $indexes [ trim ( $v , '()' )])){
if ( is_array ( $v )){
$alterIndexList [] = 'DROP INDEX ix_' . strtolower ( $tableName ) . '_' . strtolower ( $v [ 'value' ]) . ';' ;
} else {
$alterIndexList [] = 'DROP INDEX ' . $indexes [ trim ( $v , '()' )][ 'indexname' ] . ';' ;
}
}
2009-04-06 01:20:09 +02:00
$alterIndexList [] = $this -> getIndexSqlDefinition ( $tableName , $k , $v );
}
2009-02-13 03:46:54 +01:00
if ( $alterList ) {
2008-11-24 00:29:09 +01:00
$alterations = implode ( " , \n " , $alterList );
$this -> query ( " ALTER TABLE \" $tableName\ " " . $alterations );
}
2009-03-04 22:55:40 +01:00
2009-05-19 23:47:48 +02:00
if ( $alteredOptions && 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 "
);
}
2009-03-04 22:55:40 +01:00
foreach ( $alterIndexList as $alteration )
$this -> query ( $alteration );
2008-11-23 02:20:39 +01:00
}
2009-02-13 03:46:54 +01:00
/*
* 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 ( isset ( $matches )) {
echo " sql: $colSpec <pre> " ;
print_r ( $matches );
echo '</pre>' ;
} */
2009-09-16 05:51:38 +02:00
if ( sizeof ( $matches ) == 0 )
return '' ;
2009-02-17 04:57:21 +01:00
if ( $matches [ 1 ] == 'serial8' )
2009-02-13 03:46:54 +01:00
return '' ;
if ( isset ( $matches [ 1 ])) {
$alterCol = " ALTER COLUMN \" $colName\ " TYPE $matches [ 1 ] \n " ;
// SET null / not null
if ( ! empty ( $matches [ 2 ])) $alterCol .= " , \n ALTER COLUMN \" $colName\ " SET $matches [ 2 ] " ;
// SET default (we drop it first, for reasons of precaution)
if ( ! empty ( $matches [ 3 ])) {
$alterCol .= " , \n ALTER COLUMN \" $colName\ " DROP DEFAULT " ;
$alterCol .= " , \n ALTER COLUMN \" $colName\ " SET $matches [ 3 ] " ;
}
// SET check constraint (The constraint HAS to be dropped)
if ( ! empty ( $matches [ 4 ])) {
$alterCol .= " , \n DROP CONSTRAINT \" { $tableName } _ { $colName } _check \" " ;
$alterCol .= " , \n ADD CONSTRAINT \" { $tableName } _ { $colName } _check \" $matches[4] " ;
}
}
return isset ( $alterCol ) ? $alterCol : '' ;
}
2008-11-23 02:20:39 +01:00
public function renameTable ( $oldTableName , $newTableName ) {
$this -> query ( " ALTER TABLE \" $oldTableName\ " RENAME \ " $newTableName\ " " );
}
/**
2009-09-29 22:59:45 +02:00
* Repairs and reindexes the table . This might take a long time on a very large table .
2008-11-23 02:20:39 +01:00
* @ 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 ) {
2009-09-29 22:59:45 +02:00
$this -> runTableCheckCommand ( " VACUUM FULL ANALYZE \" $tableName\ " " );
$this -> runTableChechCommand ( " REINDEX TABLE \" $tableName\ " " );
2008-11-23 02:20:39 +01:00
return true ;
}
/**
* Helper function used by checkAndRepairTable .
* @ param string $sql Query to run .
2009-09-29 22:59:45 +02:00
* @ return boolean Returns true no matter what ; we ' re not currently checking the status of the command
2008-11-23 02:20:39 +01:00
*/
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 " );
}
2008-11-24 00:29:09 +01:00
/**
* Change the database column name of the given field .
*
* @ param string $tableName The name of the tbale the field is in .
* @ param string $oldName The name of the field to change .
* @ param string $newName The new name of the field
*/
public function renameField ( $tableName , $oldName , $newName ) {
$fieldList = $this -> fieldList ( $tableName );
if ( array_key_exists ( $oldName , $fieldList )) {
2009-02-13 03:46:54 +01:00
$this -> query ( " ALTER TABLE \" $tableName\ " RENAME COLUMN \ " $oldName\ " TO \ " $newName\ " " );
2008-11-24 00:29:09 +01:00
}
}
2008-11-23 02:20:39 +01:00
public function fieldList ( $table ) {
2009-02-17 04:57:21 +01:00
//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....
$fields = $this -> query ( " SELECT ordinal_position, column_name, data_type, column_default, is_nullable, character_maximum_length, numeric_precision FROM information_schema.columns WHERE table_name = ' $table ' ORDER BY ordinal_position; " );
2008-11-24 00:29:09 +01:00
$output = array ();
2008-11-24 00:52:06 +01:00
if ( $fields ) foreach ( $fields as $field ) {
2009-03-03 22:46:27 +01:00
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 ();
2009-09-16 05:51:38 +02:00
$enum = '' ;
2009-03-03 22:46:27 +01:00
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 ; $i < strlen ( $value ); $i ++ ){
$char = substr ( $value , $i , 1 );
if ( $in_value )
$current_value .= $char ;
if ( $char == " ' " ){
if ( ! $in_value )
$in_value = true ;
else {
$in_value = false ;
$constraints [] = substr ( $current_value , 0 , - 1 );
$current_value = '' ;
}
}
}
if ( sizeof ( $constraints ) > 0 ){
//Get the default:
//TODO: perhaps pass this to the enum function so we can
$default = trim ( substr ( $field [ 'column_default' ], 0 , strpos ( $field [ 'column_default' ], '::' )), " ' " );
2009-09-16 05:51:38 +02:00
$output [ $field [ 'column_name' ]] = $this -> enum ( Array ( 'default' => $default , 'name' => $field [ 'column_name' ], 'enums' => $constraints ));
2009-03-03 22:46:27 +01:00
}
2009-09-16 05:51:38 +02:00
} else {
$output [ $field [ 'column_name' ]] = 'varchar(' . $field [ 'character_maximum_length' ] . ')' ;
2009-03-03 22:46:27 +01:00
}
2009-09-16 05:51:38 +02:00
break ;
2009-03-03 22:46:27 +01:00
2009-09-16 05:51:38 +02:00
case 'numeric' :
$output [ $field [ 'column_name' ]] = 'numeric(' . $field [ 'numeric_precision' ] . ')' ;
2009-02-17 04:57:21 +01:00
break ;
default :
$output [ $field [ 'column_name' ]] = $field ;
}
2008-11-23 02:20:39 +01:00
}
2008-11-24 00:29:09 +01:00
return $output ;
2008-11-23 02:20:39 +01:00
}
/**
* 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 ) {
$this -> query ( $this -> getIndexSqlDefinition ( $tableName , $indexName , $indexSpec ));
}
2009-01-09 05:01:37 +01:00
/*
* 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 .
*/
2009-03-04 22:55:40 +01:00
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' :
2009-09-16 05:51:38 +02:00
$indexSpec = '(ts_' . $indexSpec [ 'name' ] . ')' ;
2009-03-04 22:55:40 +01:00
break ;
case 'unique' :
$indexSpec = 'unique (' . $indexSpec [ 'value' ] . ')' ;
break ;
case 'btree' :
$indexSpec = 'using btree (' . $indexSpec [ 'value' ] . ')' ;
break ;
case 'hash' :
$indexSpec = 'using hash (' . $indexSpec [ 'value' ] . ')' ;
break ;
}
2009-01-09 05:01:37 +01:00
}
2009-03-04 22:55:40 +01:00
} else {
$indexSpec = 'ix_' . $table . '_' . $indexSpec ;
2009-01-09 05:01:37 +01:00
}
2009-02-17 04:57:21 +01:00
return $indexSpec ;
2009-01-09 05:01:37 +01:00
}
2009-03-04 22:55:40 +01:00
protected function getIndexSqlDefinition ( $tableName , $indexName , $indexSpec , $asDbValue = false ) {
2009-02-13 03:46:54 +01:00
2009-09-17 02:10:30 +02:00
//TODO: create table partition support
2009-09-16 05:51:38 +02:00
//TODO: create clustering options
2009-03-04 22:55:40 +01:00
if ( ! $asDbValue ){
2009-09-16 05:51:38 +02:00
$tableCol = 'ix_' . $tableName . '_' . $indexName ;
if ( strlen ( $tableCol ) > 64 ){
$tableCol = substr ( $indexName , 0 , 59 ) . rand ( 1000 , 9999 );
//echo 'it is now ' . $tableCol . "\n\n";
}
2009-03-04 22:55:40 +01:00
if ( ! is_array ( $indexSpec )){
$indexSpec = trim ( $indexSpec , '()' );
$bits = explode ( ',' , $indexSpec );
$indexes = " \" " . implode ( " \" , \" " , $bits ) . " \" " ;
2009-09-16 05:51:38 +02:00
$indexSpec = $this -> indexList ( $tableName );
2009-03-04 22:55:40 +01:00
2009-09-16 05:51:38 +02:00
return " create index $tableCol ON \" " . $tableName . " \" ( " . $indexes . " ); " ;
2009-03-04 22:55:40 +01:00
} else {
2009-09-16 05:51:38 +02:00
//Misc options first:
$fillfactor = $where = '' ;;
if ( isset ( $indexSpec [ 'fillfactor' ]))
$fillfactor = 'WITH (FILLFACTOR = ' . $indexSpec [ 'fillfactor' ] . ')' ;
if ( isset ( $indexSpec [ 'where' ]))
$where = 'WHERE ' . $indexSpec [ 'where' ];
//TODO: create tablespace and where clause support
2009-03-04 22:55:40 +01:00
//create a type-specific index
2009-09-16 05:51:38 +02:00
//NOTE: hash should be removed. This is only here to demonstrate how other indexes can be made
2009-03-04 22:55:40 +01:00
switch ( $indexSpec [ 'type' ]){
case 'fulltext' :
2009-09-29 23:59:05 +02:00
$spec = " create index $tableCol ON \" " . $tableName . " \" USING " . $this -> default_fts_cluster_method . " ( \" ts_ " . $indexName . " \" ) $fillfactor $where " ;
2009-03-04 22:55:40 +01:00
break ;
case 'unique' :
2009-09-16 05:51:38 +02:00
$spec = " create unique index $tableCol ON \" " . $tableName . " \" ( \" " . $indexSpec [ 'value' ] . " \" ) $fillfactor $where " ;
2009-03-04 22:55:40 +01:00
break ;
case 'btree' :
2009-09-16 05:51:38 +02:00
$spec = " create index $tableCol ON \" " . $tableName . " \" USING btree ( \" " . $indexSpec [ 'value' ] . " \" ) $fillfactor $where " ;
2009-03-04 22:55:40 +01:00
break ;
case 'hash' :
2009-09-16 05:51:38 +02:00
//NOTE: this is not a recommended index type
$spec = " create index $tableCol ON \" " . $tableName . " \" USING hash ( \" " . $indexSpec [ 'value' ] . " \" ) $fillfactor $where " ;
2009-03-04 22:55:40 +01:00
break ;
2009-02-13 03:46:54 +01:00
2009-03-04 22:55:40 +01:00
default :
2009-09-16 05:51:38 +02:00
$spec = " create index $tableCol ON \" " . $tableName . " \" ( \" " . $indexSpec [ 'value' ] . " \" ) $fillfactor $where " ;
2009-03-04 22:55:40 +01:00
}
2009-09-16 05:51:38 +02:00
return trim ( $spec ) . ';' ;
2009-03-04 22:55:40 +01:00
}
} else {
$indexName = trim ( $indexName , '()' );
return $indexName ;
2008-11-23 02:20:39 +01:00
}
2009-03-04 22:55:40 +01:00
}
function getDbSqlDefinition ( $tableName , $indexName , $indexSpec ){
return $this -> getIndexSqlDefinition ( $tableName , $indexName , $indexSpec , true );
2008-11-23 02:20:39 +01:00
}
/**
* 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 " );
}
/**
* Return the list of indexes in a table .
* @ param string $table The table name .
* @ return array
*/
public function indexList ( $table ) {
2009-03-04 22:55:40 +01:00
2009-02-13 03:46:54 +01:00
//Retrieve a list of indexes for the specified table
2009-03-04 22:55:40 +01:00
$indexes = DB :: query ( " SELECT tablename, indexname, indexdef FROM pg_indexes WHERE tablename=' $table '; " );
2008-11-23 02:20:39 +01:00
2009-09-16 05:51:38 +02:00
$indexList = Array ();
2009-03-04 22:55:40 +01:00
foreach ( $indexes as $index ) {
//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 ' ;
$value = explode ( ' ' , substr ( $index [ 'indexdef' ], strpos ( $index [ 'indexdef' ], ' USING ' ) + 7 ));
if ( sizeof ( $value ) > 2 ){
for ( $i = 2 ; $i < sizeof ( $value ); $i ++ )
$value [ 1 ] .= $value [ $i ];
}
2009-09-17 02:10:30 +02:00
$key = substr ( $value [ 1 ], 0 , strpos ( $value [ 1 ], ')' ));
$key = trim ( trim ( str_replace ( " \" " , '' , $key ), '()' ));
2009-03-04 22:55:40 +01:00
$indexList [ $key ][ 'indexname' ] = $index [ 'indexname' ];
$indexList [ $key ][ 'spec' ] = $prefix . '(' . $key . ')' ;
}
2009-02-13 03:46:54 +01:00
2009-09-16 05:51:38 +02:00
return isset ( $indexList ) ? $indexList : null ;
2008-11-23 02:20:39 +01:00
}
/**
* Returns a list of all the tables in the database .
* Table names will all be in lowercase .
* @ return array
*/
public function tableList () {
foreach ( $this -> query ( " SELECT tablename FROM pg_tables WHERE tablename NOT ILIKE 'pg_%' AND tablename NOT ILIKE 'sql_%' " ) as $record ) {
2009-09-16 05:51:38 +02:00
//$table = strtolower(reset($record));
$table = reset ( $record );
2008-11-23 02:20:39 +01:00
$tables [ $table ] = $table ;
}
2009-09-16 05:51:38 +02:00
//Return an empty array if there's nothing in this database
return isset ( $tables ) ? $tables : Array ();
}
function TableExists ( $tableName ){
$result = $this -> query ( " SELECT tablename FROM pg_tables WHERE tablename=' $tableName '; " ) -> first ();
if ( $result )
return true ;
else
return false ;
2008-11-23 02:20:39 +01:00
}
/**
* 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 ){
$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)); " ;
$result = DB :: query ( $query );
$table = Array ();
while ( $row = pg_fetch_assoc ( $result )){
$table [] = Array ( 'Column' => $row [ 'Column' ], 'DataType' => $row [ 'DataType' ]);
}
return $table ;
}
2009-09-16 05:51:38 +02:00
/**
* 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\ " ; " );
}
}
2008-11-23 02:20:39 +01:00
/**
* Return a boolean type - formatted string
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
2009-02-17 04:57:21 +01:00
public function boolean ( $values , $asDbValue = false ){
//Annoyingly, we need to do a good ol' fashioned switch here:
2009-03-12 22:58:20 +01:00
( $values [ 'default' ]) ? $default = '1' : $default = '0' ;
2008-11-23 02:20:39 +01:00
2009-02-17 04:57:21 +01:00
if ( $asDbValue )
2009-03-12 22:58:20 +01:00
return Array ( 'data_type' => 'smallint' );
2009-09-29 22:59:45 +02:00
else {
if ( $values [ 'arrayValue' ] != '' )
$default = '' ;
else
$default = ' default ' . ( int ) $values [ 'default' ];
return " smallint { $values [ 'arrayValue' ] } " . $default ;
}
2008-11-23 02:20:39 +01:00
}
/**
* Return a date type - formatted string
* For MySQL , we simply return the word 'date' , no other parameters are necessary
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
public function date ( $values ){
//For reference, this is what typically gets passed to this function:
//$parts=Array('datatype'=>'date');
//DB::requireField($this->tableName, $this->name, "date");
2009-09-29 22:59:45 +02:00
return " date { $values [ 'arrayValue' ] } " ;
2008-11-23 02:20:39 +01:00
}
/**
* Return a decimal type - formatted string
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
2009-02-17 04:57:21 +01:00
public function decimal ( $values , $asDbValue = false ){
2008-11-23 02:20:39 +01:00
//For reference, this is what typically gets passed to this function:
//$parts=Array('datatype'=>'decimal', 'precision'=>"$this->wholeSize,$this->decimalSize");
//DB::requireField($this->tableName, $this->name, "decimal($this->wholeSize,$this->decimalSize)");
2009-02-17 04:57:21 +01:00
// Avoid empty strings being put in the db
if ( $values [ 'precision' ] == '' ) {
$precision = 1 ;
} else {
$precision = $values [ 'precision' ];
}
if ( $asDbValue )
2009-09-16 05:51:38 +02:00
return Array ( 'data_type' => 'numeric' , 'precision' => '9' );
2009-09-29 22:59:45 +02:00
else return " decimal( $precision ) { $values [ 'arrayValue' ] } " ;
2008-11-23 02:20:39 +01:00
}
/**
* 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 ){
2009-02-17 04:57:21 +01:00
//Enums are a bit different. We'll be creating a varchar(255) with a constraint of all the usual enum options.
2008-11-23 02:20:39 +01:00
//NOTE: In this one instance, we are including the table name in the values array
2009-09-29 22:59:45 +02:00
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' ]) . " ')) " ;
2008-11-23 02:20:39 +01:00
}
/**
* Return a float type - formatted string
* For MySQL , we simply return the word 'date' , no other parameters are necessary
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
2009-02-17 04:57:21 +01:00
public function float ( $values , $asDbValue = false ){
2008-11-23 02:20:39 +01:00
//For reference, this is what typically gets passed to this function:
//$parts=Array('datatype'=>'float');
//DB::requireField($this->tableName, $this->name, "float");
2009-02-17 04:57:21 +01:00
if ( $asDbValue )
return Array ( 'data_type' => 'double precision' );
2009-09-29 22:59:45 +02:00
else return " float { $values [ 'arrayValue' ] } " ;
2008-11-23 02:20:39 +01:00
}
/**
* Return a int type - formatted string
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
2009-02-17 04:57:21 +01:00
public function int ( $values , $asDbValue = false ){
if ( $asDbValue )
2009-09-16 05:51:38 +02:00
return Array ( 'data_type' => 'numeric' , 'precision' => $values [ 'precision' ]);
2009-09-29 22:59:45 +02:00
else {
if ( $values [ 'arrayValue' ] != '' )
$default = '' ;
else
$default = ' default ' . ( int ) $values [ 'default' ];
return " numeric(11) { $values [ 'arrayValue' ] } " . $default ;
}
2008-11-23 02:20:39 +01:00
}
/**
* 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
*/
2009-02-17 04:57:21 +01:00
public function ssdatetime ( $values , $asDbValue = false ){
2008-11-23 02:20:39 +01:00
//For reference, this is what typically gets passed to this function:
//$parts=Array('datatype'=>'datetime');
//DB::requireField($this->tableName, $this->name, $values);
2009-02-17 04:57:21 +01:00
if ( $asDbValue )
return Array ( 'data_type' => 'timestamp without time zone' );
else
2009-09-29 22:59:45 +02:00
return " timestamp { $values [ 'arrayValue' ] } " ;
2008-11-23 02:20:39 +01:00
}
/**
* Return a text type - formatted string
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
2009-02-17 04:57:21 +01:00
public function text ( $values , $asDbValue = false ){
2008-11-23 02:20:39 +01:00
//For reference, this is what typically gets passed to this function:
//$parts=Array('datatype'=>'mediumtext', 'character set'=>'utf8', 'collate'=>'utf8_general_ci');
//DB::requireField($this->tableName, $this->name, "mediumtext character set utf8 collate utf8_general_ci");
2009-02-17 04:57:21 +01:00
if ( $asDbValue )
return Array ( 'data_type' => 'text' );
else
2009-09-29 22:59:45 +02:00
return " text { $values [ 'arrayValue' ] } " ;
2008-11-23 02:20:39 +01:00
}
/**
* Return a time type - formatted string
* For MySQL , we simply return the word 'time' , no other parameters are necessary
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
public function time ( $values ){
//For reference, this is what typically gets passed to this function:
//$parts=Array('datatype'=>'time');
//DB::requireField($this->tableName, $this->name, "time");
2009-09-29 22:59:45 +02:00
return " time { $values [ 'arrayValue' ] } " ;
2008-11-23 02:20:39 +01:00
}
/**
* Return a varchar type - formatted string
*
* @ params array $values Contains a tokenised list of info about this data type
* @ return string
*/
2009-02-17 04:57:21 +01:00
public function varchar ( $values , $asDbValue = false ){
2008-11-23 02:20:39 +01:00
//For reference, this is what typically gets passed to this function:
//$parts=Array('datatype'=>'varchar', 'precision'=>$this->size, 'character set'=>'utf8', 'collate'=>'utf8_general_ci');
//DB::requireField($this->tableName, $this->name, "varchar($this->size) character set utf8 collate utf8_general_ci");
2009-09-16 05:51:38 +02:00
if ( ! isset ( $values [ 'precision' ]))
$values [ 'precision' ] = 255 ;
2009-02-17 04:57:21 +01:00
if ( $asDbValue )
2009-09-16 05:51:38 +02:00
return Array ( 'data_type' => 'varchar' , 'precision' => $values [ 'precision' ]);
2009-02-17 04:57:21 +01:00
else
2009-09-29 22:59:45 +02:00
return " varchar( { $values [ 'precision' ] } ) { $values [ 'arrayValue' ] } " ;
2009-02-17 04:57:21 +01:00
}
/*
* Return a 4 digit numeric type . MySQL has a proprietary 'Year' type .
*/
public function year ( $values , $asDbValue = false ){
if ( $asDbValue )
2009-09-16 05:51:38 +02:00
return Array ( 'data_type' => 'numeric' , 'precision' => '4' );
2009-09-29 22:59:45 +02:00
else return " numeric(4) { $values [ 'arrayValue' ] } " ;
2008-11-23 02:20:39 +01:00
}
function escape_character ( $escape = false ){
if ( $escape )
return " \\ \" " ;
else
return " \" " ;
}
/**
2009-03-03 22:46:27 +01:00
* Create a fulltext search datatype for PostgreSQL
2008-11-23 02:20:39 +01:00
*
* @ param array $spec
*/
2009-09-29 23:59:05 +02:00
/* function fulltext ( $table , $spec ){
2008-11-23 02:20:39 +01:00
//$spec['name'] is the column we've created that holds all the words we want to index.
//This is a coalesced collection of multiple columns if necessary
2009-09-29 23:59:05 +02:00
$spec = 'create index ix_' . $table . '_' . $spec [ 'name' ] . ' on ' . $table . ' using ' . $this -> default_fts_cluster_method . '(' . $spec [ 'name' ] . ');' ;
2008-11-23 02:20:39 +01:00
return $spec ;
2009-09-29 23:59:05 +02:00
} */
2008-11-24 00:29:09 +01:00
2009-02-13 03:46:54 +01:00
/**
* 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
*/
2009-02-17 04:57:21 +01:00
function IdColumn ( $asDbValue = false ){
if ( $asDbValue )
return 'bigint' ;
else return 'serial8 not null' ;
2009-02-13 03:46:54 +01:00
}
2008-11-24 00:29:09 +01:00
/**
* Returns true if this table exists
* @ todo Make a proper implementation
*/
function hasTable ( $tableName ) {
return true ;
}
2009-03-12 03:48:48 +01:00
/**
* Returns the SQL command to get all the tables in this database
*/
function allTablesSQL (){
return " select table_name from information_schema.tables where table_schema='public' and table_type='BASE TABLE'; " ;
}
2008-11-24 00:29:09 +01:00
/**
* Return enum values for the given field
* @ todo Make a proper implementation
*/
function enumValuesForField ( $tableName , $fieldName ) {
return array ( 'SiteTree' , 'Page' );
}
2009-03-12 03:48:48 +01:00
/**
* Because NOW () doesn ' t always work ...
* MSSQL , I ' m looking at you
*
*/
function now (){
return 'NOW()' ;
}
2009-09-16 05:51:38 +02:00
/*
* Returns the database - specific version of the random () function
*/
function random (){
return 'RANDOM()' ;
}
2008-11-24 00:29:09 +01:00
/**
* Convert a SQLQuery object into a SQL statement
* @ todo There is a lot of duplication between this and MySQLDatabase :: sqlQueryToString () . Perhaps they could both call a common
* helper function in Database ?
*/
public function sqlQueryToString ( SQLQuery $sqlQuery ) {
if ( ! $sqlQuery -> from ) return '' ;
$distinct = $sqlQuery -> distinct ? " DISTINCT " : " " ;
if ( $sqlQuery -> delete ) {
$text = " DELETE " ;
} else if ( $sqlQuery -> select ) {
$text = " SELECT $distinct " . implode ( " , " , $sqlQuery -> select );
}
$text .= " FROM " . implode ( " " , $sqlQuery -> from );
if ( $sqlQuery -> where ) $text .= " WHERE ( " . $sqlQuery -> getFilter () . " ) " ;
if ( $sqlQuery -> groupby ) $text .= " GROUP BY " . implode ( " , " , $sqlQuery -> groupby );
if ( $sqlQuery -> having ) $text .= " HAVING ( " . implode ( " ) AND ( " , $sqlQuery -> having ) . " ) " ;
if ( $sqlQuery -> orderby ) $text .= " ORDER BY " . $sqlQuery -> orderby ;
if ( $sqlQuery -> limit ) {
$limit = $sqlQuery -> limit ;
// Pass limit as array or SQL string value
if ( is_array ( $limit )) {
if ( ! array_key_exists ( 'limit' , $limit )) user_error ( 'SQLQuery::limit(): Wrong format for $limit' , E_USER_ERROR );
if ( isset ( $limit [ 'start' ]) && is_numeric ( $limit [ 'start' ]) && isset ( $limit [ 'limit' ]) && is_numeric ( $limit [ 'limit' ])) {
$combinedLimit = ( int ) $limit [ 'start' ] . ',' . ( int ) $limit [ 'limit' ];
} elseif ( isset ( $limit [ 'limit' ]) && is_numeric ( $limit [ 'limit' ])) {
$combinedLimit = ( int ) $limit [ 'limit' ];
} else {
$combinedLimit = false ;
}
if ( ! empty ( $combinedLimit )) $this -> limit = $combinedLimit ;
} else {
2009-09-29 22:59:45 +02:00
if ( strpos ( $sqlQuery -> limit , ',' )){
$limit = str_replace ( ',' , ' LIMIT ' , $sqlQuery -> limit );
$text .= ' OFFSET ' . $limit ;
} else {
$text .= ' LIMIT ' . $sqlQuery -> limit ;
}
2008-11-24 00:29:09 +01:00
}
}
return $text ;
}
2009-03-12 03:48:48 +01:00
/*
* 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 ){
return pg_escape_string ( $value );
}
2009-04-06 01:20:09 +02:00
/*
* This changes the index name depending on database requirements .
* MySQL doesn ' t need any changes .
*/
function modifyIndex ( $index , $spec ){
if ( is_array ( $spec ) && $spec [ 'type' ] == 'fulltext' )
return 'ts_' . str_replace ( ',' , '_' , $index );
else
return str_replace ( '_' , ',' , $index );
}
2009-09-16 05:51:38 +02:00
/**
* The core search engine configuration .
* @ todo There is no result relevancy or ordering as it currently stands .
*
* @ param string $keywords Keywords as a space separated string
* @ return object DataObjectSet of result pages
*/
public function searchEngine ( $classesToSearch , $keywords , $start , $pageLength , $sortBy = " Relevance DESC " , $extraFilter = " " , $booleanSearch = false , $alternativeFileFilter = " " , $invertedMatch = false ) {
$keywords = Convert :: raw2sql ( trim ( $keywords ));
$htmlEntityKeywords = htmlentities ( $keywords );
/* $keywordList = explode ( ' ' , $keywords );
if ( $keywordList ) {
foreach ( $keywordList as $index => $keyword ) {
$keywordList [ $index ] = " ' { $keyword } ' " ;
}
$keywords = implode ( ' AND ' , $keywordList );
} */
/* $htmlEntityKeywordList = explode ( ' ' , $htmlEntityKeywords );
if ( $htmlEntityKeywordList ) {
foreach ( $htmlEntityKeywordList as $index => $keyword ) {
$htmlEntityKeywordList [ $index ] = " \" { $keyword } \" " ;
}
$htmlEntityKeywords = implode ( ' AND ' , $htmlEntityKeywordList );
} */
//We can get a list of all the tsvector columns though this query:
$result = DB :: query ( " SELECT table_name, column_name, data_type FROM information_schema.columns WHERE data_type='tsvector'; " );
if ( ! $result -> numRecords ()) throw Exception ( 'there are no full text columns to search' );
$tables = Array ();
foreach ( $result as $row ){
if ( substr ( $row [ 'table_name' ], - 5 ) != '_Live' && substr ( $row [ 'table_name' ], - 9 ) != '_versions' ) {
2009-09-29 23:59:05 +02:00
$thisSql = " SELECT \" ID \" , ' { $row [ 'table_name' ] } ' AS ClassName, ts_rank( \" { $row [ 'column_name' ] } \" , q) FROM \" { $row [ 'table_name' ] } \" , to_tsquery('english', ' $keywords ') AS q WHERE \" { $row [ 'column_name' ] } \" " . $this -> default_fts_search_method . " q " ;
2009-09-16 05:51:38 +02:00
$tables [] = $thisSql ;
}
}
$doSet = new DataObjectSet ();
$sortBy = 'ts_rank' ;
$limit = 10 ;
$fullQuery = " SELECT * FROM ( " . implode ( " UNION " , $tables ) . " ) AS q1 ORDER BY $sortBy LIMIT $limit " ;
$totalCount = 1 ;
// Get records
$records = DB :: query ( $fullQuery );
foreach ( $records as $record ){
$item = DB :: query ( " SELECT * FROM \" { $record [ 'classname' ] } \" WHERE \" ID \" = { $record [ 'ID' ] } ; " ) -> first ();
$objects [] = new $record [ 'classname' ]( $item );
}
if ( isset ( $objects )) $doSet = new DataObjectSet ( $objects );
else $doSet = new DataObjectSet ();
$doSet -> setPageLimits ( $start , $pageLength , $totalCount );
//$resultRows=Array();
//Right, now we go and run each of these queries and take their rank and put them into an array accordinaly
//$totalCount=0;
//foreach($tables as $sql){
// $result=DB::query($sql);
// foreach($result as $row){
//
// $resultRows[$row['ts_rank']][]=Array('ID'=>$row['ID'], 'Table'=>$row['source']);
// $totalCount++;
// }
//}
//Now we populate the dataobject with the results in order of relevance:
/* foreach ( $resultRows as $row_array ){
foreach ( $row_array as $row ){
$item = DataObject :: get_by_id ( $row [ 'Table' ], $row [ 'ID' ]);
$searchResults -> push ( $item );
}
}
/*$searchResults->setPageLimits($start, $pageLength, $totalCount);*/
return $doSet ;
}
2008-11-23 02:20:39 +01:00
}
/**
* A result - set from a MySQL database .
* @ package sapphire
* @ subpackage model
*/
class PostgreSQLQuery extends Query {
/**
* The MySQLDatabase object that created this result set .
* @ var MySQLDatabase
*/
private $database ;
/**
* The internal MySQL 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 mysql handle that is points to the resultset .
*/
public function __construct ( PostgreSQLDatabase $database , $handle ) {
$this -> database = $database ;
$this -> handle = $handle ;
}
public function __destroy () {
2009-09-16 05:51:38 +02:00
pg_free_result ( $this -> handle );
2008-11-23 02:20:39 +01:00
}
public function seek ( $row ) {
2009-09-16 05:51:38 +02:00
return pg_result_seek ( $this - handle , $row );
2008-11-23 02:20:39 +01:00
}
public function numRecords () {
return pg_num_rows ( $this -> handle );
}
public function nextRecord () {
// Coalesce rather than replace common fields.
if ( $data = pg_fetch_row ( $this -> handle )) {
foreach ( $data as $columnIdx => $value ) {
$columnName = pg_field_name ( $this -> handle , $columnIdx );
// $value || !$ouput[$columnName] means that the *last* occurring value is shown
// !$ouput[$columnName] means that the *first* occurring value is shown
if ( isset ( $value ) || ! isset ( $output [ $columnName ])) {
$output [ $columnName ] = $value ;
}
}
return $output ;
} else {
return false ;
}
}
}
?>