2010-01-30 05:45:10 +00:00
< ? php
2019-07-25 00:43:25 +01:00
// This file is part of GNU social - https://www.gnu.org/software/social
//
// GNU social is free software: you can redistribute it and/or modify
// it under the terms of the GNU Affero General Public License as published by
// the Free Software Foundation, either version 3 of the License, or
// (at your option) any later version.
//
// GNU social is distributed in the hope that it will be useful,
// but WITHOUT ANY WARRANTY; without even the implied warranty of
// MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
// GNU Affero General Public License for more details.
//
// You should have received a copy of the GNU Affero General Public License
// along with GNU social. If not, see <http://www.gnu.org/licenses/>.
2010-01-30 05:45:10 +00:00
/**
2019-07-25 00:43:25 +01:00
* Database schema for PostgreSQL
2010-01-30 05:45:10 +00:00
*
2019-09-11 06:15:16 +01:00
* @ category Database
* @ package GNUsocial
* @ author Evan Prodromou < evan @ status . net >
* @ author Brenda Wallace < shiny @ cpan . org >
* @ author Brion Vibber < brion @ status . net >
2019-07-25 00:43:25 +01:00
* @ copyright 2019 Free Software Foundation , Inc http :// www . fsf . org
* @ license https :// www . gnu . org / licenses / agpl . html GNU AGPL v3 or later
2010-01-30 05:45:10 +00:00
*/
2019-07-25 00:43:25 +01:00
defined ( 'GNUSOCIAL' ) || die ();
2010-01-30 05:45:10 +00:00
/**
2019-07-25 00:43:25 +01:00
* Class representing the database schema for PostgreSQL
2010-01-30 05:45:10 +00:00
*
* A class representing the database schema . Can be used to
* manipulate the schema -- especially for plugins and upgrade
* utilities .
*
2019-07-25 00:43:25 +01:00
* @ copyright 2019 Free Software Foundation , Inc http :// www . fsf . org
* @ license https :// www . gnu . org / licenses / agpl . html GNU AGPL v3 or later
2010-01-30 05:45:10 +00:00
*/
class PgsqlSchema extends Schema
{
/**
2010-10-09 00:36:32 +01:00
* Returns a table definition array for the table
2010-01-30 05:45:10 +00:00
* in the schema with the given name .
*
* Throws an exception if the table is not found .
*
2010-10-09 00:36:32 +01:00
* @ param string $table Name of the table to get
2010-01-30 05:45:10 +00:00
*
2010-10-09 00:36:32 +01:00
* @ return array tabledef for that table .
2019-07-25 00:43:25 +01:00
* @ throws SchemaTableMissingException
2010-01-30 05:45:10 +00:00
*/
2010-10-09 00:36:32 +01:00
public function getTableDef ( $table )
2010-01-30 05:45:10 +00:00
{
2019-07-25 00:43:25 +01:00
$def = [];
2010-10-09 00:36:32 +01:00
$hasKeys = false ;
2010-01-30 05:45:10 +00:00
2010-10-09 00:36:32 +01:00
// Pull column data from INFORMATION_SCHEMA
$columns = $this -> fetchMetaInfo ( $table , 'columns' , 'ordinal_position' );
if ( count ( $columns ) == 0 ) {
throw new SchemaTableMissingException ( " No such table: $table " );
2010-01-30 05:45:10 +00:00
}
2010-10-11 22:15:02 +01:00
// We'll need to match up fields by ordinal reference
2019-07-25 00:43:25 +01:00
$orderedFields = [];
2010-10-11 22:15:02 +01:00
2010-10-09 00:36:32 +01:00
foreach ( $columns as $row ) {
$name = $row [ 'column_name' ];
2010-10-11 22:15:02 +01:00
$orderedFields [ $row [ 'ordinal_position' ]] = $name ;
2019-07-25 00:43:25 +01:00
$field = [];
$field [ 'type' ] = $type = $row [ 'udt_name' ];
2010-01-30 05:45:10 +00:00
2010-10-09 00:36:32 +01:00
if ( $type == 'char' || $type == 'varchar' ) {
if ( $row [ 'character_maximum_length' ] !== null ) {
$field [ 'length' ] = intval ( $row [ 'character_maximum_length' ]);
}
}
if ( $type == 'numeric' ) {
// Other int types may report these values, but they're irrelevant.
// Just ignore them!
if ( $row [ 'numeric_precision' ] !== null ) {
$field [ 'precision' ] = intval ( $row [ 'numeric_precision' ]);
}
if ( $row [ 'numeric_scale' ] !== null ) {
$field [ 'scale' ] = intval ( $row [ 'numeric_scale' ]);
}
}
if ( $row [ 'is_nullable' ] == 'NO' ) {
$field [ 'not null' ] = true ;
}
if ( $row [ 'column_default' ] !== null ) {
$field [ 'default' ] = $row [ 'column_default' ];
if ( $this -> isNumericType ( $type )) {
$field [ 'default' ] = intval ( $field [ 'default' ]);
}
}
2010-01-30 05:45:10 +00:00
2010-10-09 00:36:32 +01:00
$def [ 'fields' ][ $name ] = $field ;
}
2010-01-30 05:45:10 +00:00
2010-10-11 22:15:02 +01:00
// Pulling index info from pg_class & pg_index
2010-10-11 23:40:51 +01:00
// This can give us primary & unique key info, but not foreign key constraints
// so we exclude them and pick them up later.
2010-10-11 22:15:02 +01:00
$indexInfo = $this -> getIndexInfo ( $table );
foreach ( $indexInfo as $row ) {
$keyName = $row [ 'key_name' ];
// Dig the column references out!
2010-10-11 23:40:51 +01:00
//
// These are inconvenient arrays with partial references to the
// pg_att table, but since we've already fetched up the column
// info on the current table, we can look those up locally.
2019-07-25 00:43:25 +01:00
$cols = [];
2010-10-11 22:15:02 +01:00
$colPositions = explode ( ' ' , $row [ 'indkey' ]);
foreach ( $colPositions as $ord ) {
if ( $ord == 0 ) {
$cols [] = 'FUNCTION' ; // @fixme
} else {
$cols [] = $orderedFields [ $ord ];
}
}
2010-10-11 23:40:51 +01:00
$def [ 'indexes' ][ $keyName ] = $cols ;
2010-10-11 22:15:02 +01:00
}
2010-10-11 23:40:51 +01:00
// Pull constraint data from INFORMATION_SCHEMA:
// Primary key, unique keys, foreign keys
2010-10-09 00:36:32 +01:00
$keyColumns = $this -> fetchMetaInfo ( $table , 'key_column_usage' , 'constraint_name,ordinal_position' );
2019-07-25 00:43:25 +01:00
$keys = [];
2010-10-09 00:36:32 +01:00
foreach ( $keyColumns as $row ) {
$keyName = $row [ 'constraint_name' ];
$keyCol = $row [ 'column_name' ];
if ( ! isset ( $keys [ $keyName ])) {
2019-07-25 00:43:25 +01:00
$keys [ $keyName ] = [];
2010-01-30 05:45:10 +00:00
}
2010-10-09 00:36:32 +01:00
$keys [ $keyName ][] = $keyCol ;
}
2010-01-30 05:45:10 +00:00
2010-10-09 00:36:32 +01:00
foreach ( $keys as $keyName => $cols ) {
2010-10-11 23:40:51 +01:00
// name hack -- is this reliable?
2010-10-11 22:15:02 +01:00
if ( $keyName == " { $table } _pkey " ) {
2010-10-11 23:40:51 +01:00
$def [ 'primary key' ] = $cols ;
2019-09-11 06:15:16 +01:00
} elseif ( preg_match ( " /^ { $table } _(.*)_fkey $ / " , $keyName , $matches )) {
2010-10-11 23:40:51 +01:00
$fkey = $this -> getForeignKeyInfo ( $table , $keyName );
$colMap = array_combine ( $cols , $fkey [ 'col_names' ]);
2019-07-25 00:43:25 +01:00
$def [ 'foreign keys' ][ $keyName ] = [ $fkey [ 'table_name' ], $colMap ];
2010-10-11 22:15:02 +01:00
} else {
2010-10-11 23:40:51 +01:00
$def [ 'unique keys' ][ $keyName ] = $cols ;
2010-10-11 22:15:02 +01:00
}
2010-10-09 00:36:32 +01:00
}
return $def ;
}
2010-01-30 05:45:10 +00:00
2010-10-09 00:36:32 +01:00
/**
* Pull some INFORMATION . SCHEMA data for the given table .
*
* @ param string $table
2019-07-25 00:43:25 +01:00
* @ param $infoTable
* @ param null $orderBy
2010-10-09 00:36:32 +01:00
* @ return array of arrays
2019-07-25 00:43:25 +01:00
* @ throws PEAR_Exception
2010-10-09 00:36:32 +01:00
*/
2019-09-11 06:15:16 +01:00
public function fetchMetaInfo ( $table , $infoTable , $orderBy = null )
2010-10-09 00:36:32 +01:00
{
$query = " SELECT * FROM information_schema.%s " .
2019-07-25 00:43:25 +01:00
" WHERE table_name='%s' " ;
2010-10-09 00:36:32 +01:00
$sql = sprintf ( $query , $infoTable , $table );
if ( $orderBy ) {
$sql .= ' ORDER BY ' . $orderBy ;
2010-01-30 05:45:10 +00:00
}
2010-10-09 00:36:32 +01:00
return $this -> fetchQueryData ( $sql );
2010-01-30 05:45:10 +00:00
}
/**
2010-10-11 22:15:02 +01:00
* Pull some PG - specific index info
* @ param string $table
* @ return array of arrays
2019-07-25 00:43:25 +01:00
* @ throws PEAR_Exception
2010-10-11 22:15:02 +01:00
*/
2019-09-11 06:15:16 +01:00
public function getIndexInfo ( $table )
2010-10-11 22:15:02 +01:00
{
$query = 'SELECT ' .
2019-07-25 00:43:25 +01:00
'(SELECT relname FROM pg_class WHERE oid=indexrelid) AS key_name, ' .
'* FROM pg_index ' .
'WHERE indrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
'AND indisprimary=\'f\' AND indisunique=\'f\' ' .
'ORDER BY indrelid, indexrelid' ;
2010-10-11 22:15:02 +01:00
$sql = sprintf ( $query , $table );
return $this -> fetchQueryData ( $sql );
}
2010-10-11 23:40:51 +01:00
/**
* Column names from the foreign table can be resolved with a call to getTableColumnNames ()
2019-07-25 00:43:25 +01:00
* @ param string $table
* @ param $constraint_name
2010-10-11 23:40:51 +01:00
* @ return array array of rows with keys : fkey_name , table_name , table_id , col_names ( array of strings )
2019-07-25 00:43:25 +01:00
* @ throws PEAR_Exception
2010-10-11 23:40:51 +01:00
*/
2019-09-11 06:15:16 +01:00
public function getForeignKeyInfo ( $table , $constraint_name )
2010-10-11 23:40:51 +01:00
{
// In a sane world, it'd be easier to query the column names directly.
// But it's pretty hard to work with arrays such as col_indexes in direct SQL here.
$query = 'SELECT ' .
2019-07-25 00:43:25 +01:00
'(SELECT relname FROM pg_class WHERE oid=confrelid) AS table_name, ' .
'confrelid AS table_id, ' .
'(SELECT indkey FROM pg_index WHERE indexrelid=conindid) AS col_indexes ' .
'FROM pg_constraint ' .
'WHERE conrelid=(SELECT oid FROM pg_class WHERE relname=\'%s\') ' .
'AND conname=\'%s\' ' .
'AND contype=\'f\'' ;
2010-10-11 23:40:51 +01:00
$sql = sprintf ( $query , $table , $constraint_name );
$data = $this -> fetchQueryData ( $sql );
if ( count ( $data ) < 1 ) {
throw new Exception ( " Could not find foreign key " . $constraint_name . " on table " . $table );
}
$row = $data [ 0 ];
2019-07-25 00:43:25 +01:00
return [
2010-10-11 23:40:51 +01:00
'table_name' => $row [ 'table_name' ],
'col_names' => $this -> getTableColumnNames ( $row [ 'table_id' ], $row [ 'col_indexes' ])
2019-07-25 00:43:25 +01:00
];
2010-10-11 23:40:51 +01:00
}
/**
*
* @ param int $table_id
* @ param array $col_indexes
* @ return array of strings
2019-07-25 00:43:25 +01:00
* @ throws PEAR_Exception
2010-10-11 23:40:51 +01:00
*/
2019-09-11 06:15:16 +01:00
public function getTableColumnNames ( $table_id , $col_indexes )
2010-10-11 23:40:51 +01:00
{
$indexes = array_map ( 'intval' , explode ( ' ' , $col_indexes ));
$query = 'SELECT attnum AS col_index, attname AS col_name ' .
2019-07-25 00:43:25 +01:00
'FROM pg_attribute where attrelid=%d ' .
'AND attnum IN (%s)' ;
2010-10-11 23:40:51 +01:00
$sql = sprintf ( $query , $table_id , implode ( ',' , $indexes ));
$data = $this -> fetchQueryData ( $sql );
2019-07-25 00:43:25 +01:00
$byId = [];
2010-10-11 23:40:51 +01:00
foreach ( $data as $row ) {
$byId [ $row [ 'col_index' ]] = $row [ 'col_name' ];
}
2019-07-25 00:43:25 +01:00
$out = [];
2010-10-11 23:40:51 +01:00
foreach ( $indexes as $id ) {
$out [] = $byId [ $id ];
}
return $out ;
}
2010-03-10 09:02:56 +00:00
/**
* Translate the ( mostly ) mysql - ish column types into somethings more standard
* @ param string column type
*
* @ return string postgres happy column type
*/
2019-07-25 00:43:25 +01:00
private function _columnTypeTranslation ( $type )
{
$map = [
'datetime' => 'timestamp' ,
];
if ( ! empty ( $map [ $type ])) {
return $map [ $type ];
}
return $type ;
2010-03-10 09:02:56 +00:00
}
2010-01-30 05:45:10 +00:00
/**
2010-08-17 00:31:18 +01:00
* Return the proper SQL for creating or
* altering a column .
2010-01-30 05:45:10 +00:00
*
2010-08-17 00:31:18 +01:00
* Appropriate for use in CREATE TABLE or
* ALTER TABLE statements .
2010-01-30 05:45:10 +00:00
*
2010-08-17 00:31:18 +01:00
* @ param array $cd column to create
2010-01-30 05:45:10 +00:00
*
2010-08-17 00:31:18 +01:00
* @ return string correct SQL for that column
2010-01-30 05:45:10 +00:00
*/
2019-09-11 06:15:16 +01:00
public function columnSql ( array $cd )
2010-01-30 05:45:10 +00:00
{
2019-07-25 00:43:25 +01:00
$line = [];
2010-10-12 03:10:51 +01:00
$line [] = parent :: columnSql ( $cd );
2010-08-17 00:31:18 +01:00
2010-10-12 03:10:51 +01:00
/*
2010-08-17 00:31:18 +01:00
if ( $table [ 'foreign keys' ][ $name ]) {
foreach ( $table [ 'foreign keys' ][ $name ] as $foreignTable => $foreignColumn ) {
$line [] = 'references' ;
2010-10-12 03:10:51 +01:00
$line [] = $this -> quoteIdentifier ( $foreignTable );
$line [] = '(' . $this -> quoteIdentifier ( $foreignColumn ) . ')' ;
2010-01-30 05:45:10 +00:00
}
}
2010-10-12 03:10:51 +01:00
*/
2010-01-30 05:45:10 +00:00
2010-08-17 00:31:18 +01:00
return implode ( ' ' , $line );
2010-01-30 05:45:10 +00:00
}
2010-10-08 02:33:02 +01:00
/**
* Append phrase ( s ) to an array of partial ALTER TABLE chunks in order
* to alter the given column from its old state to a new one .
*
* @ param array $phrase
* @ param string $columnName
* @ param array $old previous column definition as found in DB
* @ param array $cd current column definition
*/
2019-09-11 06:15:16 +01:00
public function appendAlterModifyColumn ( array & $phrase , $columnName , array $old , array $cd )
2010-10-08 02:33:02 +01:00
{
$prefix = 'ALTER COLUMN ' . $this -> quoteIdentifier ( $columnName ) . ' ' ;
$oldType = $this -> mapType ( $old );
$newType = $this -> mapType ( $cd );
if ( $oldType != $newType ) {
2010-10-11 21:05:44 +01:00
$phrase [] = $prefix . 'TYPE ' . $newType ;
2010-10-08 02:33:02 +01:00
}
if ( ! empty ( $old [ 'not null' ]) && empty ( $cd [ 'not null' ])) {
2010-10-11 21:05:44 +01:00
$phrase [] = $prefix . 'DROP NOT NULL' ;
2019-09-11 06:15:16 +01:00
} elseif ( empty ( $old [ 'not null' ]) && ! empty ( $cd [ 'not null' ])) {
2010-10-11 21:05:44 +01:00
$phrase [] = $prefix . 'SET NOT NULL' ;
2010-10-08 02:33:02 +01:00
}
if ( isset ( $old [ 'default' ]) && ! isset ( $cd [ 'default' ])) {
2010-10-11 21:05:44 +01:00
$phrase [] = $prefix . 'DROP DEFAULT' ;
2019-09-11 06:15:16 +01:00
} elseif ( ! isset ( $old [ 'default' ]) && isset ( $cd [ 'default' ])) {
2010-10-11 21:05:44 +01:00
$phrase [] = $prefix . 'SET DEFAULT ' . $this -> quoteDefaultValue ( $cd );
2010-10-08 02:33:02 +01:00
}
}
2010-10-19 20:23:49 +01:00
/**
* Append an SQL statement to drop an index from a table .
* Note that in PostgreSQL , index names are DB - unique .
*
* @ param array $statements
* @ param string $table
* @ param string $name
*/
2019-09-11 06:15:16 +01:00
public function appendDropIndex ( array & $statements , $table , $name )
2010-10-19 20:23:49 +01:00
{
$statements [] = " DROP INDEX $name " ;
}
2019-09-11 06:15:16 +01:00
public function mapType ( $column )
2010-01-30 05:45:10 +00:00
{
2019-07-25 00:43:25 +01:00
$map = [
2019-09-11 09:25:39 +01:00
'serial' => 'bigserial' , // FIXME: creates the wrong name for the sequence for some internal sequence-lookup function, so better fix this to do the real 'create sequence' dance.
'bool' => 'boolean' ,
'numeric' => 'decimal' ,
2019-07-25 00:43:25 +01:00
'datetime' => 'timestamp' ,
2019-09-11 09:25:39 +01:00
'blob' => 'bytea' ,
2019-07-25 00:43:25 +01:00
];
2010-08-17 00:31:18 +01:00
$type = $column [ 'type' ];
if ( isset ( $map [ $type ])) {
$type = $map [ $type ];
2010-05-15 03:56:40 +01:00
}
2010-10-19 01:21:12 +01:00
if ( $type == 'int' ) {
if ( ! empty ( $column [ 'size' ])) {
$size = $column [ 'size' ];
if ( $size == 'small' ) {
return 'int2' ;
2019-09-11 06:15:16 +01:00
} elseif ( $size == 'big' ) {
2010-10-19 01:21:12 +01:00
return 'int8' ;
}
2010-08-17 00:31:18 +01:00
}
2010-10-19 01:21:12 +01:00
return 'int4' ;
2010-01-30 05:45:10 +00:00
}
2010-08-17 00:31:18 +01:00
return $type ;
}
// @fixme need name... :P
2019-09-11 06:15:16 +01:00
public function typeAndSize ( $column )
2010-08-17 00:31:18 +01:00
{
if ( $column [ 'type' ] == 'enum' ) {
2019-07-25 00:43:25 +01:00
$vals = array_map ([ $this , 'quote' ], $column [ 'enum' ]);
2010-08-17 00:31:18 +01:00
return " text check ( $name in " . implode ( ',' , $vals ) . ')' ;
2010-01-30 05:45:10 +00:00
} else {
2010-08-17 00:31:18 +01:00
return parent :: typeAndSize ( $column );
2010-01-30 05:45:10 +00:00
}
}
2010-08-17 00:31:18 +01:00
2010-10-14 00:04:28 +01:00
/**
* Filter the given table definition array to match features available
* in this database .
*
* This lets us strip out unsupported things like comments , foreign keys ,
* or type variants that we wouldn ' t get back from getTableDef () .
*
* @ param array $tableDef
2019-07-25 00:43:25 +01:00
* @ return array
2010-10-14 00:04:28 +01:00
*/
2019-09-11 06:15:16 +01:00
public function filterDef ( array $tableDef )
2010-10-14 00:04:28 +01:00
{
2010-10-14 00:21:24 +01:00
foreach ( $tableDef [ 'fields' ] as $name => & $col ) {
2010-10-14 00:04:28 +01:00
// No convenient support for field descriptions
unset ( $col [ 'description' ]);
2010-10-16 00:32:37 +01:00
/*
2010-10-14 00:04:28 +01:00
if ( isset ( $col [ 'size' ])) {
// Don't distinguish between tinyint and int.
if ( $col [ 'size' ] == 'tiny' && $col [ 'type' ] == 'int' ) {
unset ( $col [ 'size' ]);
}
}
2010-10-16 00:32:37 +01:00
*/
$col [ 'type' ] = $this -> mapType ( $col );
unset ( $col [ 'size' ]);
2010-10-14 00:04:28 +01:00
}
2010-10-19 02:26:11 +01:00
if ( ! empty ( $tableDef [ 'primary key' ])) {
$tableDef [ 'primary key' ] = $this -> filterKeyDef ( $tableDef [ 'primary key' ]);
}
if ( ! empty ( $tableDef [ 'unique keys' ])) {
foreach ( $tableDef [ 'unique keys' ] as $i => $def ) {
$tableDef [ 'unique keys' ][ $i ] = $this -> filterKeyDef ( $def );
}
}
2010-10-14 00:04:28 +01:00
return $tableDef ;
}
2010-10-19 02:26:11 +01:00
/**
* Filter the given key / index definition to match features available
* in this database .
*
* @ param array $def
* @ return array
*/
2019-09-11 06:15:16 +01:00
public function filterKeyDef ( array $def )
2010-10-19 02:26:11 +01:00
{
// PostgreSQL doesn't like prefix lengths specified on keys...?
2019-07-25 00:43:25 +01:00
foreach ( $def as $i => $item ) {
2010-10-19 02:26:11 +01:00
if ( is_array ( $item )) {
$def [ $i ] = $item [ 0 ];
}
}
return $def ;
}
2010-01-30 05:45:10 +00:00
}