Search moodle.org's
Developer Documentation

See Release Notes
Long Term Support Release

  • Bug fixes for general core bugs in 4.1.x will end 13 November 2023 (12 months).
  • Bug fixes for security issues in 4.1.x will end 10 November 2025 (36 months).
  • PHP version: minimum PHP 7.4.0 Note: minimum PHP version has increased since Moodle 4.0. PHP 8.0.x is supported too.

Differences Between: [Versions 310 and 401] [Versions 311 and 401] [Versions 39 and 401] [Versions 400 and 401] [Versions 401 and 403]

   1  <?php
   2  /**
   3   * Data Dictionary for PostgreSQL.
   4   *
   5   * This file is part of ADOdb, a Database Abstraction Layer library for PHP.
   6   *
   7   * @package ADOdb
   8   * @link https://adodb.org Project's web site and documentation
   9   * @link https://github.com/ADOdb/ADOdb Source code and issue tracker
  10   *
  11   * The ADOdb Library is dual-licensed, released under both the BSD 3-Clause
  12   * and the GNU Lesser General Public Licence (LGPL) v2.1 or, at your option,
  13   * any later version. This means you can use it in proprietary products.
  14   * See the LICENSE.md file distributed with this source code for details.
  15   * @license BSD-3-Clause
  16   * @license LGPL-2.1-or-later
  17   *
  18   * @copyright 2000-2013 John Lim
  19   * @copyright 2014 Damien Regad, Mark Newnham and the ADOdb community
  20   */
  21  
  22  // security - hide paths
  23  if (!defined('ADODB_DIR')) die();
  24  
  25  class ADODB2_postgres extends ADODB_DataDict
  26  {
  27  	 var $databaseType = 'postgres';
  28  	 var $seqField = false;
  29  	 var $seqPrefix = 'SEQ_';
  30  	 var $addCol = ' ADD COLUMN';
  31  	 var $quote = '"';
  32  	 var $renameTable = 'ALTER TABLE %s RENAME TO %s'; // at least since 7.1
  33  	 var $dropTable = 'DROP TABLE %s CASCADE';
  34  
  35  	 public $blobAllowsDefaultValue = true;
  36  	 public $blobAllowsNotNull = true;
  37  
  38  	function metaType($t, $len=-1, $fieldobj=false)
  39  	 {
  40  	 	 if (is_object($t)) {
  41  	 	 	 $fieldobj = $t;
  42  	 	 	 $t = $fieldobj->type;
  43  	 	 	 $len = $fieldobj->max_length;
  44  	 	 }
  45  
  46  	 	 $t = strtoupper($t);
  47  
  48  	 	 if (array_key_exists($t,$this->connection->customActualTypes))
  49  	 	 	 return  $this->connection->customActualTypes[$t];
  50  
  51  	 	 $is_serial = is_object($fieldobj) && !empty($fieldobj->primary_key) && !empty($fieldobj->unique) &&
  52  	 	 	 !empty($fieldobj->has_default) && substr($fieldobj->default_value,0,8) == 'nextval(';
  53  
  54  	 	 switch ($t) {
  55  
  56  	 	 	 case 'INTERVAL':
  57  	 	 	 case 'CHAR':
  58  	 	 	 case 'CHARACTER':
  59  	 	 	 case 'VARCHAR':
  60  	 	 	 case 'NAME':
  61  	 	 	 case 'BPCHAR':
  62  	 	 	 	 if ($len <= $this->blobSize) return 'C';
  63  
  64  	 	 	 case 'TEXT':
  65  	 	 	 	 return 'X';
  66  
  67  	 	 	 case 'IMAGE': // user defined type
  68  	 	 	 case 'BLOB': // user defined type
  69  	 	 	 case 'BIT':	 // This is a bit string, not a single bit, so don't return 'L'
  70  	 	 	 case 'VARBIT':
  71  	 	 	 case 'BYTEA':
  72  	 	 	 	 return 'B';
  73  
  74  	 	 	 case 'BOOL':
  75  	 	 	 case 'BOOLEAN':
  76  	 	 	 	 return 'L';
  77  
  78  	 	 	 case 'DATE':
  79  	 	 	 	 return 'D';
  80  
  81  	 	 	 case 'TIME':
  82  	 	 	 case 'DATETIME':
  83  	 	 	 case 'TIMESTAMP':
  84  	 	 	 case 'TIMESTAMPTZ':
  85  	 	 	 	 return 'T';
  86  
  87  	 	 	 case 'INTEGER': return !$is_serial ? 'I' : 'R';
  88  	 	 	 case 'SMALLINT':
  89  	 	 	 case 'INT2': return !$is_serial ? 'I2' : 'R';
  90  	 	 	 case 'INT4': return !$is_serial ? 'I4' : 'R';
  91  	 	 	 case 'BIGINT':
  92  	 	 	 case 'INT8': return !$is_serial ? 'I8' : 'R';
  93  
  94  	 	 	 case 'OID':
  95  	 	 	 case 'SERIAL':
  96  	 	 	 	 return 'R';
  97  
  98  	 	 	 case 'FLOAT4':
  99  	 	 	 case 'FLOAT8':
 100  	 	 	 case 'DOUBLE PRECISION':
 101  	 	 	 case 'REAL':
 102  	 	 	 	 return 'F';
 103  
 104  	 	 	 default:
 105  	 	 	 	 return ADODB_DEFAULT_METATYPE;
 106  	 	 }
 107  	 }
 108  
 109  	function actualType($meta)
 110  	 {
 111  	 	 $meta = strtoupper($meta);
 112  
 113  	 	 /*
 114  	 	 * Add support for custom meta types. We do this
 115  	 	 * first, that allows us to override existing types
 116  	 	 */
 117  	 	 if (isset($this->connection->customMetaTypes[$meta]))
 118  	 	 	 return $this->connection->customMetaTypes[$meta]['actual'];
 119  
 120  	 	 switch ($meta) {
 121  	 	 case 'C': return 'VARCHAR';
 122  	 	 case 'XL':
 123  	 	 case 'X': return 'TEXT';
 124  
 125  	 	 case 'C2': return 'VARCHAR';
 126  	 	 case 'X2': return 'TEXT';
 127  
 128  	 	 case 'B': return 'BYTEA';
 129  
 130  	 	 case 'D': return 'DATE';
 131  	 	 case 'TS':
 132  	 	 case 'T': return 'TIMESTAMP';
 133  
 134  	 	 case 'L': return 'BOOLEAN';
 135  	 	 case 'I': return 'INTEGER';
 136  	 	 case 'I1': return 'SMALLINT';
 137  	 	 case 'I2': return 'INT2';
 138  	 	 case 'I4': return 'INT4';
 139  	 	 case 'I8': return 'INT8';
 140  
 141  	 	 case 'F': return 'FLOAT8';
 142  	 	 case 'N': return 'NUMERIC';
 143  	 	 default:
 144  	 	 	 return $meta;
 145  	 	 }
 146  	 }
 147  
 148  	 /**
 149  	  * Adding a new Column
 150  	  *
 151  	  * reimplementation of the default function as postgres does NOT allow to set the default in the same statement
 152  	  *
 153  	  * @param string $tabname table-name
 154  	  * @param string $flds column-names and types for the changed columns
 155  	  * @return array with SQL strings
 156  	  */
 157  	function addColumnSQL($tabname, $flds)
 158  	 {
 159  	 	 $tabname = $this->tableName($tabname);
 160  	 	 $sql = array();
 161  	 	 $not_null = false;
 162  	 	 list($lines,$pkey) = $this->_genFields($flds);
 163  	 	 $alter = 'ALTER TABLE ' . $tabname . $this->addCol . ' ';
 164  	 	 foreach($lines as $v) {
 165  	 	 	 if (($not_null = preg_match('/NOT NULL/i',$v))) {
 166  	 	 	 	 $v = preg_replace('/NOT NULL/i','',$v);
 167  	 	 	 }
 168  	 	 	 if (preg_match('/^([^ ]+) .*DEFAULT (\'[^\']+\'|\"[^\"]+\"|[^ ]+)/',$v,$matches)) {
 169  	 	 	 	 list(,$colname,$default) = $matches;
 170  	 	 	 	 $sql[] = $alter . str_replace('DEFAULT '.$default,'',$v);
 171  	 	 	 	 $sql[] = 'UPDATE '.$tabname.' SET '.$colname.'='.$default.' WHERE '.$colname.' IS NULL ';
 172  	 	 	 	 $sql[] = 'ALTER TABLE '.$tabname.' ALTER COLUMN '.$colname.' SET DEFAULT ' . $default;
 173  	 	 	 } else {
 174  	 	 	 	 $sql[] = $alter . $v;
 175  	 	 	 }
 176  	 	 	 if ($not_null) {
 177  	 	 	 	 list($colname) = explode(' ',$v);
 178  	 	 	 	 $sql[] = 'ALTER TABLE '.$tabname.' ALTER COLUMN '.$colname.' SET NOT NULL';
 179  	 	 	 }
 180  	 	 }
 181  	 	 return $sql;
 182  	 }
 183  
 184  
 185  	function dropIndexSQL($idxname, $tabname = NULL)
 186  	 {
 187  	 	 return array(sprintf($this->dropIndex, $this->tableName($idxname), $this->tableName($tabname)));
 188  	 }
 189  
 190  	 /**
 191  	  * Change the definition of one column
 192  	  *
 193  	  * Postgres can't do that on its own, you need to supply the complete
 194  	  * definition of the new table, to allow recreating the table and copying
 195  	  * the content over to the new table.
 196  	  *
 197  	  * @param string $tabname      table-name
 198  	  * @param string $flds         column-name and type for the changed column
 199  	  * @param string $tableflds    complete definition of the new table, e.g. for postgres, default ''
 200  	  * @param array  $tableoptions options for the new table {@see CreateTableSQL()}, default ''
 201  	  *
 202  	  * @return array with SQL strings
 203  	  */
 204  	function alterColumnSQL($tabname, $flds, $tableflds='', $tableoptions='')
 205  	 {
 206  	 	 // Check if alter single column datatype available - works with 8.0+
 207  	 	 $has_alter_column = 8.0 <= (float) @$this->serverInfo['version'];
 208  
 209  	 	 if ($has_alter_column) {
 210  	 	 	 $tabname = $this->tableName($tabname);
 211  	 	 	 $sql = array();
 212  	 	 	 list($lines,$pkey) = $this->_genFields($flds);
 213  	 	 	 $set_null = false;
 214  	 	 	 foreach($lines as $v) {
 215  	 	 	 	 $alter = 'ALTER TABLE ' . $tabname . $this->alterCol . ' ';
 216  	 	 	 	 if ($not_null = preg_match('/NOT NULL/i',$v)) {
 217  	 	 	 	 	 $v = preg_replace('/NOT NULL/i','',$v);
 218  	 	 	 	 }
 219  	 	 	 	 // this next block doesn't work - there is no way that I can see to
 220  	 	 	 	 // explicitly ask a column to be null using $flds
 221  	 	 	 	 elseif ($set_null = preg_match('/NULL/i',$v)) {
 222  	 	 	 	 	 // if they didn't specify not null, see if they explicitly asked for null
 223  	 	 	 	 	 // Lookbehind pattern covers the case 'fieldname NULL datatype DEFAULT NULL'
 224  	 	 	 	 	 // only the first NULL should be removed, not the one specifying
 225  	 	 	 	 	 // the default value
 226  	 	 	 	 	 $v = preg_replace('/(?<!DEFAULT)\sNULL/i','',$v);
 227  	 	 	 	 }
 228  
 229  	 	 	 	 if (preg_match('/^([^ ]+) .*DEFAULT (\'[^\']+\'|\"[^\"]+\"|[^ ]+)/',$v,$matches)) {
 230  	 	 	 	 	 $existing = $this->metaColumns($tabname);
 231  	 	 	 	 	 list(,$colname,$default) = $matches;
 232  	 	 	 	 	 $alter .= $colname;
 233  	 	 	 	 	 if ($this->connection) {
 234  	 	 	 	 	 	 $old_coltype = $this->connection->metaType($existing[strtoupper($colname)]);
 235  	 	 	 	 	 } else {
 236  	 	 	 	 	 	 $old_coltype = $t;
 237  	 	 	 	 	 }
 238  	 	 	 	 	 $v = preg_replace('/^' . preg_quote($colname) . '\s/', '', $v);
 239  	 	 	 	 	 $t = trim(str_replace('DEFAULT '.$default,'',$v));
 240  
 241  	 	 	 	 	 // Type change from bool to int
 242  	 	 	 	 	 if ( $old_coltype == 'L' && $t == 'INTEGER' ) {
 243  	 	 	 	 	 	 $sql[] = $alter . ' DROP DEFAULT';
 244  	 	 	 	 	 	 $sql[] = $alter . " TYPE $t USING ($colname::BOOL)::INT";
 245  	 	 	 	 	 	 $sql[] = $alter . " SET DEFAULT $default";
 246  	 	 	 	 	 }
 247  	 	 	 	 	 // Type change from int to bool
 248  	 	 	 	 	 else if ( $old_coltype == 'I' && $t == 'BOOLEAN' ) {
 249  	 	 	 	 	 	 if( strcasecmp('NULL', trim($default)) != 0 ) {
 250  	 	 	 	 	 	 	 $default = $this->connection->qstr($default);
 251  	 	 	 	 	 	 }
 252  	 	 	 	 	 	 $sql[] = $alter . ' DROP DEFAULT';
 253  	 	 	 	 	 	 $sql[] = $alter . " TYPE $t USING CASE WHEN $colname = 0 THEN false ELSE true END";
 254  	 	 	 	 	 	 $sql[] = $alter . " SET DEFAULT $default";
 255  	 	 	 	 	 }
 256  	 	 	 	 	 // Any other column types conversion
 257  	 	 	 	 	 else {
 258  	 	 	 	 	 	 $sql[] = $alter . " TYPE $t";
 259  	 	 	 	 	 	 $sql[] = $alter . " SET DEFAULT $default";
 260  	 	 	 	 	 }
 261  
 262  	 	 	 	 }
 263  	 	 	 	 else {
 264  	 	 	 	 	 // drop default?
 265  	 	 	 	 	 preg_match ('/^\s*(\S+)\s+(.*)$/',$v,$matches);
 266  	 	 	 	 	 list (,$colname,$rest) = $matches;
 267  	 	 	 	 	 $alter .= $colname;
 268  	 	 	 	 	 $sql[] = $alter . ' TYPE ' . $rest;
 269  	 	 	 	 }
 270  
 271  	 	 	 	 #list($colname) = explode(' ',$v);
 272  	 	 	 	 if ($not_null) {
 273  	 	 	 	 	 // this does not error out if the column is already not null
 274  	 	 	 	 	 $sql[] = $alter . ' SET NOT NULL';
 275  	 	 	 	 }
 276  	 	 	 	 if ($set_null) {
 277  	 	 	 	 	 // this does not error out if the column is already null
 278  	 	 	 	 	 $sql[] = $alter . ' DROP NOT NULL';
 279  	 	 	 	 }
 280  	 	 	 }
 281  	 	 	 return $sql;
 282  	 	 }
 283  
 284  	 	 // does not have alter column
 285  	 	 if (!$tableflds) {
 286  	 	 	 if ($this->debug) ADOConnection::outp("AlterColumnSQL needs a complete table-definiton for PostgreSQL");
 287  	 	 	 return array();
 288  	 	 }
 289  	 	 return $this->_recreate_copy_table($tabname, false, $tableflds,$tableoptions);
 290  	 }
 291  
 292  	 /**
 293  	  * Drop one column
 294  	  *
 295  	  * Postgres < 7.3 can't do that on it's own, you need to supply the complete definition of the new table,
 296  	  * to allow, recreating the table and copying the content over to the new table
 297  	  * @param string $tabname table-name
 298  	  * @param string $flds column-name and type for the changed column
 299  	  * @param string $tableflds complete definition of the new table, eg. for postgres, default ''
 300  	  * @param array  $tableoptions options for the new table {@see CreateTableSQL}, default []
 301  	  * @return array with SQL strings
 302  	  */
 303  	function dropColumnSQL($tabname, $flds, $tableflds='', $tableoptions='')
 304  	 {
 305  	 	 $has_drop_column = 7.3 <= (float) @$this->serverInfo['version'];
 306  	 	 if (!$has_drop_column && !$tableflds) {
 307  	 	 	 if ($this->debug) {
 308  	 	 	 	 ADOConnection::outp("dropColumnSQL needs complete table-definiton for PostgreSQL < 7.3");
 309  	 	 	 }
 310  	 	 	 return array();
 311  	 	 }
 312  	 	 if ($has_drop_column) {
 313  	 	 	 return ADODB_DataDict::dropColumnSQL($tabname, $flds);
 314  	 	 }
 315  	 	 return $this->_recreate_copy_table($tabname, $flds, $tableflds, $tableoptions);
 316  	 }
 317  
 318  	 /**
 319  	  * Save the content into a temp. table, drop and recreate the original table and copy the content back in
 320  	  *
 321  	  * We also take care to set the values of the sequenz and recreate the indexes.
 322  	  * All this is done in a transaction, to not loose the content of the table, if something went wrong!
 323  	  * @internal
 324  	  * @param string $tabname table-name
 325  	  * @param string $dropflds column-names to drop
 326  	  * @param string $tableflds complete definition of the new table, eg. for postgres
 327  	  * @param array|string $tableoptions options for the new table see CreateTableSQL, default ''
 328  	  * @return array with SQL strings
 329  	  */
 330  	function _recreate_copy_table($tabname, $dropflds, $tableflds, $tableoptions='')
 331  	 {
 332  	 	 if ($dropflds && !is_array($dropflds)) $dropflds = explode(',',$dropflds);
 333  	 	 $copyflds = array();
 334  	 	 foreach($this->metaColumns($tabname) as $fld) {
 335  	 	 	 if (preg_match('/'.$fld->name.' (\w+)/i', $tableflds, $matches)) {
 336  	 	 	 	 $new_type = strtoupper($matches[1]);
 337  	 	 	 	 // AlterColumn of a char column to a nummeric one needs an explicit conversation
 338  	 	 	 	 if (in_array($new_type, array('I', 'I2', 'I4', 'I8', 'N', 'F')) &&
 339  	 	 	 	 	 in_array($fld->type, array('varchar','char','text','bytea'))
 340  	 	 	 	 ) {
 341  	 	 	 	 	 $copyflds[] = "to_number($fld->name,'S9999999999999D99')";
 342  	 	 	 	 } else {
 343  	 	 	 	 	 // other column-type changes needs explicit decode, encode for bytea or cast otherwise
 344  	 	 	 	 	 $new_actual_type = $this->actualType($new_type);
 345  	 	 	 	 	 if (strtoupper($fld->type) != $new_actual_type) {
 346  	 	 	 	 	 	 if ($new_actual_type == 'BYTEA' && $fld->type == 'text') {
 347  	 	 	 	 	 	 	 $copyflds[] = "DECODE($fld->name, 'escape')";
 348  	 	 	 	 	 	 } elseif ($fld->type == 'bytea' && $new_actual_type == 'TEXT') {
 349  	 	 	 	 	 	 	 $copyflds[] = "ENCODE($fld->name, 'escape')";
 350  	 	 	 	 	 	 } else {
 351  	 	 	 	 	 	 	 $copyflds[] = "CAST($fld->name AS $new_actual_type)";
 352  	 	 	 	 	 	 }
 353  	 	 	 	 	 }
 354  	 	 	 	 }
 355  	 	 	 } else {
 356  	 	 	 	 $copyflds[] = $fld->name;
 357  	 	 	 }
 358  	 	 	 // identify the sequence name and the fld its on
 359  	 	 	 if ($fld->primary_key && $fld->has_default &&
 360  	 	 	 	 preg_match("/nextval\('([^']+)'::(text|regclass)\)/", $fld->default_value, $matches)) {
 361  	 	 	 	 $seq_name = $matches[1];
 362  	 	 	 	 $seq_fld = $fld->name;
 363  	 	 	 }
 364  	 	 }
 365  	 	 $copyflds = implode(', ', $copyflds);
 366  
 367  	 	 $tempname = $tabname.'_tmp';
 368  	 	 $aSql[] = 'BEGIN';	 	 // we use a transaction, to make sure not to loose the content of the table
 369  	 	 $aSql[] = "SELECT * INTO TEMPORARY TABLE $tempname FROM $tabname";
 370  	 	 $aSql = array_merge($aSql,$this->dropTableSQL($tabname));
 371  	 	 $aSql = array_merge($aSql,$this->createTableSQL($tabname, $tableflds, $tableoptions));
 372  	 	 $aSql[] = "INSERT INTO $tabname SELECT $copyflds FROM $tempname";
 373  	 	 if ($seq_name && $seq_fld) {	 // if we have a sequence we need to set it again
 374  	 	 	 $seq_name = $tabname.'_'.$seq_fld.'_seq';	 // has to be the name of the new implicit sequence
 375  	 	 	 $aSql[] = "SELECT setval('$seq_name', MAX($seq_fld)) FROM $tabname";
 376  	 	 }
 377  	 	 $aSql[] = "DROP TABLE $tempname";
 378  	 	 // recreate the indexes, if they not contain one of the dropped columns
 379  	 	 foreach($this->metaIndexes($tabname) as $idx_name => $idx_data) {
 380  	 	 	 if (substr($idx_name,-5) != '_pkey' && (!$dropflds || !count(array_intersect($dropflds,$idx_data['columns'])))) {
 381  	 	 	 	 $aSql = array_merge($aSql,$this->createIndexSQL($idx_name, $tabname, $idx_data['columns'],
 382  	 	 	 	 	 $idx_data['unique'] ? array('UNIQUE') : false));
 383  	 	 	 }
 384  	 	 }
 385  	 	 $aSql[] = 'COMMIT';
 386  	 	 return $aSql;
 387  	 }
 388  
 389  	function dropTableSQL($tabname)
 390  	 {
 391  	 	 $sql = ADODB_DataDict::dropTableSQL($tabname);
 392  
 393  	 	 $drop_seq = $this->_dropAutoIncrement($tabname);
 394  	 	 if ($drop_seq) {
 395  	 	 	 $sql[] = $drop_seq;
 396  	 	 }
 397  	 	 return $sql;
 398  	 }
 399  
 400  	 // return string must begin with space
 401  	function _createSuffix($fname, &$ftype, $fnotnull, $fdefault, $fautoinc, $fconstraint, $funsigned)
 402  	 {
 403  	 	 if ($fautoinc) {
 404  	 	 	 $ftype = 'SERIAL';
 405  	 	 	 return '';
 406  	 	 }
 407  	 	 $suffix = '';
 408  	 	 if (strlen($fdefault)) $suffix .= " DEFAULT $fdefault";
 409  	 	 if ($fnotnull) $suffix .= ' NOT NULL';
 410  	 	 if ($fconstraint) $suffix .= ' '.$fconstraint;
 411  	 	 return $suffix;
 412  	 }
 413  
 414  	 // search for a sequence for the given table (asumes the seqence-name contains the table-name!)
 415  	 // if yes return sql to drop it
 416  	 // this is still necessary if postgres < 7.3 or the SERIAL was created on an earlier version!!!
 417  	function _dropAutoIncrement($tabname)
 418  	 {
 419  	 	 $tabname = $this->connection->quote('%'.$tabname.'%');
 420  
 421  	 	 $seq = $this->connection->getOne("SELECT relname FROM pg_class WHERE NOT relname ~ 'pg_.*' AND relname LIKE $tabname AND relkind='S'");
 422  
 423  	 	 // check if a tables depends on the sequence and it therefore can't and don't need to be dropped separately
 424  	 	 if (!$seq || $this->connection->getOne("SELECT relname FROM pg_class JOIN pg_depend ON pg_class.relfilenode=pg_depend.objid WHERE relname='$seq' AND relkind='S' AND deptype='i'")) {
 425  	 	 	 return false;
 426  	 	 }
 427  	 	 return "DROP SEQUENCE ".$seq;
 428  	 }
 429  
 430  	function renameTableSQL($tabname, $newname)
 431  	 {
 432  	 	 if (!empty($this->schema)) {
 433  	 	 	 $rename_from = $this->tableName($tabname);
 434  	 	 	 $schema_save = $this->schema;
 435  	 	 	 $this->schema = false;
 436  	 	 	 $rename_to = $this->tableName($newname);
 437  	 	 	 $this->schema = $schema_save;
 438  	 	 	 return array (sprintf($this->renameTable, $rename_from, $rename_to));
 439  	 	 }
 440  
 441  	 	 return array (sprintf($this->renameTable, $this->tableName($tabname), $this->tableName($newname)));
 442  	 }
 443  
 444  	 /*
 445  	 CREATE [ [ LOCAL ] { TEMPORARY | TEMP } ] TABLE table_name (
 446  	 { column_name data_type [ DEFAULT default_expr ] [ column_constraint [, ... ] ]
 447  	 | table_constraint } [, ... ]
 448  	 )
 449  	 [ INHERITS ( parent_table [, ... ] ) ]
 450  	 [ WITH OIDS | WITHOUT OIDS ]
 451  	 where column_constraint is:
 452  	 [ CONSTRAINT constraint_name ]
 453  	 { NOT NULL | NULL | UNIQUE | PRIMARY KEY |
 454  	 CHECK (expression) |
 455  	 REFERENCES reftable [ ( refcolumn ) ] [ MATCH FULL | MATCH PARTIAL ]
 456  	 [ ON DELETE action ] [ ON UPDATE action ] }
 457  	 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
 458  	 and table_constraint is:
 459  	 [ CONSTRAINT constraint_name ]
 460  	 { UNIQUE ( column_name [, ... ] ) |
 461  	 PRIMARY KEY ( column_name [, ... ] ) |
 462  	 CHECK ( expression ) |
 463  	 FOREIGN KEY ( column_name [, ... ] ) REFERENCES reftable [ ( refcolumn [, ... ] ) ]
 464  	 [ MATCH FULL | MATCH PARTIAL ] [ ON DELETE action ] [ ON UPDATE action ] }
 465  	 [ DEFERRABLE | NOT DEFERRABLE ] [ INITIALLY DEFERRED | INITIALLY IMMEDIATE ]
 466  	 */
 467  
 468  
 469  	 /*
 470  	 CREATE [ UNIQUE ] INDEX index_name ON table
 471  [ USING acc_method ] ( column [ ops_name ] [, ...] )
 472  [ WHERE predicate ]
 473  CREATE [ UNIQUE ] INDEX index_name ON table
 474  [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] )
 475  [ WHERE predicate ]
 476  	 */
 477  	function _indexSQL($idxname, $tabname, $flds, $idxoptions)
 478  	 {
 479  	 	 $sql = array();
 480  
 481  	 	 if ( isset($idxoptions['REPLACE']) || isset($idxoptions['DROP']) ) {
 482  	 	 	 $sql[] = sprintf ($this->dropIndex, $idxname, $tabname);
 483  	 	 	 if ( isset($idxoptions['DROP']) ) {
 484  	 	 	 	 return $sql;
 485  	 	 	 }
 486  	 	 }
 487  
 488  	 	 if (empty($flds)) {
 489  	 	 	 return $sql;
 490  	 	 }
 491  
 492  	 	 $unique = isset($idxoptions['UNIQUE']) ? ' UNIQUE' : '';
 493  
 494  	 	 $s = 'CREATE' . $unique . ' INDEX ' . $idxname . ' ON ' . $tabname . ' ';
 495  
 496  	 	 if (isset($idxoptions['HASH'])) {
 497  	 	 	 $s .= 'USING HASH ';
 498  	 	 }
 499  
 500  	 	 if (isset($idxoptions[$this->upperName])) {
 501  	 	 	 $s .= $idxoptions[$this->upperName];
 502  	 	 }
 503  
 504  	 	 if (is_array($flds)) {
 505  	 	 	 $flds = implode(', ', $flds);
 506  	 	 }
 507  	 	 $s .= '(' . $flds . ')';
 508  	 	 $sql[] = $s;
 509  
 510  	 	 return $sql;
 511  	 }
 512  
 513  	function _getSize($ftype, $ty, $fsize, $fprec, $options=false)
 514  	 {
 515  	 	 if (strlen($fsize) && $ty != 'X' && $ty != 'B' && $ty  != 'I' && strpos($ftype,'(') === false) {
 516  	 	 	 $ftype .= "(".$fsize;
 517  	 	 	 if (strlen($fprec)) $ftype .= ",".$fprec;
 518  	 	 	 $ftype .= ')';
 519  	 	 }
 520  
 521  	 	 /*
 522  	 	 * Handle additional options
 523  	 	 */
 524  	 	 if (is_array($options)) {
 525  	 	 	 foreach($options as $type=>$value) {
 526  	 	 	 	 switch ($type) {
 527  	 	 	 	 	 case 'ENUM':
 528  	 	 	 	 	 	 $ftype .= '(' . $value . ')';
 529  	 	 	 	 	 	 break;
 530  	 	 	 	 	 default:
 531  	 	 	 	 }
 532  	 	 	 }
 533  	 	 }
 534  	 	 return $ftype;
 535  	 }
 536  
 537  	function changeTableSQL($tablename, $flds, $tableoptions = false, $dropOldFlds=false)
 538  	 {
 539  	 	 global $ADODB_FETCH_MODE;
 540  	 	 parent::changeTableSQL($tablename, $flds);
 541  	 	 $save = $ADODB_FETCH_MODE;
 542  	 	 $ADODB_FETCH_MODE = ADODB_FETCH_ASSOC;
 543  	 	 if ($this->connection->fetchMode !== false) {
 544  	 	 	 $savem = $this->connection->setFetchMode(false);
 545  	 	 }
 546  
 547  	 	 // check table exists
 548  	 	 $save_handler = $this->connection->raiseErrorFn;
 549  	 	 $this->connection->raiseErrorFn = '';
 550  	 	 $cols = $this->metaColumns($tablename);
 551  	 	 $this->connection->raiseErrorFn = $save_handler;
 552  
 553  	 	 if (isset($savem)) {
 554  	 	 	 $this->connection->setFetchMode($savem);
 555  	 	 }
 556  	 	 $ADODB_FETCH_MODE = $save;
 557  
 558  	 	 $sqlResult=array();
 559  	 	 if ( empty($cols)) {
 560  	 	 	 $sqlResult=$this->createTableSQL($tablename, $flds, $tableoptions);
 561  	 	 } else {
 562  	 	 	 $sqlResultAdd = $this->addColumnSQL($tablename, $flds);
 563  	 	 	 $sqlResultAlter = $this->alterColumnSQL($tablename, $flds, '', $tableoptions);
 564  	 	 	 $sqlResult = array_merge((array)$sqlResultAdd, (array)$sqlResultAlter);
 565  
 566  	 	 	 if ($dropOldFlds) {
 567  	 	 	 	 // already exists, alter table instead
 568  	 	 	 	 list($lines,$pkey,$idxs) = $this->_genFields($flds);
 569  	 	 	 	 // genfields can return FALSE at times
 570  	 	 	 	 if ($lines == null) {
 571  	 	 	 	 	 $lines = array();
 572  	 	 	 	 }
 573  	 	 	 	 $alter = 'ALTER TABLE ' . $this->tableName($tablename);
 574  	 	 	 	 foreach ( $cols as $id => $v ) {
 575  	 	 	 	 	 if ( !isset($lines[$id]) ) {
 576  	 	 	 	 	 	 $sqlResult[] = $alter . $this->dropCol . ' ' . $v->name;
 577  	 	 	 	 	 }
 578  	 	 	 	 }
 579  	 	 	 }
 580  
 581  	 	 }
 582  	 	 return $sqlResult;
 583  	 }
 584  } // end class