enable DB upgrade
authorKonrad Rosenbaum <konrad@silmor.de>
Wed, 10 Feb 2016 21:14:41 +0000 (22:14 +0100)
committerKonrad Rosenbaum <konrad@silmor.de>
Wed, 10 Feb 2016 21:14:41 +0000 (22:14 +0100)
phpbase/db.php
phpbase/db_mysql.php
phpbase/db_pgsql.php

index c36a5f1..c9e3afa 100644 (file)
@@ -1,5 +1,5 @@
 <?php
-// Copyright (C) 2009-2011 by Konrad Rosenbaum <konrad@silmor.de>
+// Copyright (C) 2009-2015 by Konrad Rosenbaum <konrad@silmor.de>
 // protected under the GNU LGPL version 3 or at your option any newer.
 // See COPYING.LGPL file that comes with this distribution.
 //
@@ -53,7 +53,7 @@ abstract class DbEngine
        
        /**returns whether the table exists; must be implemented by driver*/
        public abstract function hasTable($tablename);
-       
+
        /**begins a transaction; must be implemented by driver; use sqlBeginTransaction to create the SQL statement!*/
        public abstract function beginTransaction();
        
@@ -80,6 +80,9 @@ abstract class DbEngine
        
        /**delete database values; returns the amount of rows deleted or false if an error occurred; use sqlDelete to create the SQL statement!*/
        public abstract function deleteRows($table,$where);
+
+       ///returns the name of the database the instance is connected to
+       public abstract function dbName();
        
        /**creates a table; the argument is an array of the form "col-name" => array("col-type", "flags"...); use sqlCreateTable() etc. to create the actual statement*/
        protected abstract function createTable($tablename,$table);
@@ -106,38 +109,48 @@ abstract class DbEngine
        
        /**returns the correct name/coding of a flag:
        primarykey, notnull, unique (implies notnull), foreignkey:$table:$col, defaultint:$val, defaultstr:$val, index*/
-       protected function columnFlag($flag,$col,$table)
+       protected function columnFlag($flag,$col,$table,$cflags)
        {
-               if($flag=="primarykey")return "PRIMARY KEY";
-               if($flag=="null")return "NULL";
-               if($flag=="notnull")return "NOT NULL";
-               if($flag=="unique")return "NOT NULL UNIQUE";
-               if($flag=="index")return "INDEX";
-               $tpa=explode(":",$flag);
-               if($tpa[0]=="foreignkey"){
-                       if(count($tpa)<3)
-                               return false;
-                       return "REFERENCES ".$this->tableName($tpa[1])."($tpa[2])";
+               if($cflags&self::COLUMN_CREATE_PKEY){
+                       if($flag=="primarykey")return "PRIMARY KEY";
                }
-               if($tpa[0]=="defaultint"){
-                       if(count($tpa)<2)
-                               return "DEFAULT NULL";
-                       return "DEFAULT ".$this->escapeInt($tpa[1]);
+               if($cflags&self::COLUMN_CREATE_NULL){
+                       if($flag=="null")return "NULL";
+                       if($flag=="notnull")return "NOT NULL";
+                       if($flag=="unique")return "NOT NULL UNIQUE";
                }
-               if($tpa[0]=="defaultstr"){
-                       if(count($tpa)<2)
-                               return "DEFAULT NULL";
-                       return "DEFAULT ".$this->escapeString($tpa[1]);
+               if($cflags&self::COLUMN_CREATE_INDEX){
+                       if($flag=="index")return "INDEX";
                }
-               if($tpa[0]=="defaultbool"){
-                       if(count($tpa)<2)
-                               return "DEFAULT NULL";
-                       return "DEFAULT ".$this->escapeBool($tpa[1]);
+               $tpa=explode(":",$flag);
+               if($cflags&self::COLUMN_CREATE_FKEY){
+                       if($tpa[0]=="foreignkey"){
+                               if(count($tpa)<3)
+                                       return false;
+                               return "REFERENCES ".$this->tableName($tpa[1])."($tpa[2])";
+                       }
                }
-               if($tpa[0]=="default"){
-                       if(count($tpa)<2)
-                               return "DEFAULT NULL";
-                       return "DEFAULT ".$this->escapeColumn($table,$col,$tpa[1]);
+               if($cflags&self::COLUMN_CREATE_DEFAULT){
+                       if($tpa[0]=="defaultint"){
+                               if(count($tpa)<2)
+                                       return "DEFAULT NULL";
+                               return "DEFAULT ".$this->escapeInt($tpa[1]);
+                       }
+                       if($tpa[0]=="defaultstr"){
+                               if(count($tpa)<2)
+                                       return "DEFAULT NULL";
+                               return "DEFAULT ".$this->escapeString($tpa[1]);
+                       }
+                       if($tpa[0]=="defaultbool"){
+                               if(count($tpa)<2)
+                                       return "DEFAULT NULL";
+                               return "DEFAULT ".$this->escapeBool($tpa[1]);
+                       }
+                       if($tpa[0]=="default"){
+                               if(count($tpa)<2)
+                                       return "DEFAULT NULL";
+                               return "DEFAULT ".$this->escapeColumn($table,$col,$tpa[1]);
+                       }
                }
        }
        
@@ -149,25 +162,45 @@ abstract class DbEngine
                reset($table);
                while(list($col,$def)=each($table)){
                        $ret.=$cm;$cm=",";
-                       //check whether this is a special column
-                       if(substr($col,0,1)==":"){
-                               if($col==":primarykey")$ret.=$this->sqlCreateTablePrimaryKey($def);
-                               else die("Unknown special column ".$col." while creating table ".$tablename);
-                       }else{
-                               //column name
-                               $ret.=$col." ";
-                               //get type
-                               $ret.=$this->dataType($def[0])." ";
-                               //get flags
-                               for($i=0;$i<count($def);$i++)
-                                       $ret.=$this->columnFlag($def[$i],$col,$tablename)." ";
-                       }
+                       $ret.=$this->sqlCreateColumn($tablename,$col,$def);
                }
                $ret.=$this->createTableExtras($tablename,$table);
                $ret.=")";
                WobTransaction::debug("Create Table Stmt: ".$ret,WobTransaction::DebugDbStatement);
                return $ret;
        }
+
+       const COLUMN_CREATE_TYPE = 1;
+       const COLUMN_CREATE_NULL = 2;
+       const COLUMN_CREATE_PKEY = 4;
+       const COLUMN_CREATE_FKEY = 8;
+       const COLUMN_CREATE_KEY = self::COLUMN_CREATE_PKEY | self::COLUMN_CREATE_FKEY;
+       const COLUMN_CREATE_DEFAULT = 16;
+       const COLUMN_CREATE_INDEX = 32;
+       const COLUMN_CREATE_ALL = 0xffff;
+
+       ///creates SQL92 part of a statement for creating a single column
+       protected function sqlCreateColumn($tablename,$columnname,$columndef,$flags=self::COLUMN_CREATE_ALL)
+       {
+               $ret="";
+               //check whether this is a special column
+               if(substr($columnname,0,1)==":"){
+                       if($columnname==":primarykey"){
+                               if($flag & self::COLUMN_CREATE_PKEY)
+                                       $ret.=$this->sqlCreateTablePrimaryKey($columndef);
+                       }else die("Unknown special column ".$columnname." while creating table ".$tablename);
+               }else{
+                       //column name
+                       $ret.=$columnname." ";
+                       //get type
+                       if($flags & self::COLUMN_CREATE_TYPE)
+                               $ret.=$this->dataType($columndef[0])." ";
+                       //get flags
+                       for($i=0;$i<count($columndef);$i++)
+                               $ret.=$this->columnFlag($columndef[$i],$columnname,$tablename,$flags)." ";
+               }
+               return $ret;
+       }
        
        /**This function can be used to amend the column definitions of a table; if overwritten it must return a string; overwrite this to implement DB specific syntax*/
        protected function createTableExtras($tablename,$table)
@@ -459,6 +492,55 @@ abstract class DbEngine
                //close transaction
                print(htmlentities($this->sqlCommitTransaction()).";\n</pre>\n");
        }
+
+       ///Upgrades the database, used by admin.php
+       public function upgradeDb($doexec=true)
+       {
+               print("<h3>Database Upgrade SQL Script</h3>\n");
+               if($doexec)
+                       print("The following commands are being executed:<p>\n");
+               else
+                       print("Please copy these commands into your database client to do a manual upgrade:<p>\n");
+               print("<pre>\n");
+               //iterate DB schema and check/create tables
+               $tabs=WobSchema::tableNames();
+               for($i=0;$i<count($tabs);$i++){
+                       print("-- checking table ".$tabs[$i]);
+                       if($this->hasTable($tabs[$i])){
+                               print(" ... exists:\n");
+                               $this->upgradeTable($tabs[$i],$doexec);
+                       }else{
+                               print(" ... does not exist, creating:\n");
+                               print("<font color=\"green\">".htmlentities($this->sqlCreateTable($tabs[$i],WobSchema::tableDefinition($tabs[$i]))).";</font>\n");
+                               //create table
+                               if($doexec){
+                                       if(!$this->createTable($tabs[$i],WobSchema::tableDefinition($tabs[$i]))){
+                                               print("<font color=\"red\">-- DB Error while creating ".$tabs[$i].": ".$this->lastError()."\n");
+                                               print("-- Last statement was: ".$this->sqlCreateTable($tabs[$i],WobSchema::tableDefinition($tabs[$i]))."\n");
+                                               $this->rollbackTransaction();
+                                               die("</pre><p>Unable to upgrade database.");
+                                       }
+                               }
+                               //insert defaults
+                               foreach(WobSchema::tableDefaults($tabs[$i]) as $def){
+                                       print("<font color=\"green\">".htmlentities($this->sqlInsert($tabs[$i],$def)).";</font>\n");
+                                       if($doexec)
+                                               $this->insert($tabs[$i],$def);
+                               }
+                       }
+               }
+               //change version
+               $ctable=WobSchema::configTable();
+               $cupdate=array(WobSchema::configValueColumn() => $this->needVersion());
+               $cwhere=WobSchema::configKeyColumn()."=". $this->escapeString(WobSchema::configVersionRow());
+               print("-- update version:\n<font color=\"green\">".$this->sqlUpdate($ctable,$cupdate,$cwhere)."</font>\n");
+               if($doexec)
+                       $this->update($ctable,$cupdate,$cwhere);
+               print("\n</pre>\nDone.\n");
+       }
+
+       ///helper for upgradeDb -> upgrades a single table
+       protected abstract function upgradeTable($tablename,$doexec);
        
        /**returns the error string of the last operation*/
        public abstract function lastError();
index 48d9580..73da9e7 100644 (file)
@@ -1,5 +1,5 @@
 <?php
-// Copyright (C) 2009-2011 by Konrad Rosenbaum <konrad@silmor.de>
+// Copyright (C) 2009-2015 by Konrad Rosenbaum <konrad@silmor.de>
 // protected under the GNU LGPL version 3 or at your option any newer.
 // See COPYING.LGPL file that comes with this distribution.
 //
@@ -48,6 +48,12 @@ class MysqlEngine extends DbEngine
        {
                $this->dbname=$dbn;
        }
+
+       ///return the name of the database
+       public function dbName()
+       {
+               return $this->dbname;
+       }
        
        /**set the name of the storage engine to be used on DB creation*/
        public function setStorageEngine($e)
@@ -92,11 +98,15 @@ class MysqlEngine extends DbEngine
        public function hasTable($tnm)
        {
                if(!WobSchema::hasTable($tnm))return false;
-               $res=mysqli_query($this->dbhdl,"select * from ".$this->tableName($tnm)." where 1=2");
+               //$res=mysqli_query($this->dbhdl,"select * from ".$this->tableName($tnm)." where 1=2");
+               $res=mysqli_query($this->dbhdl,"select * from information_schema.tables where table_schema=".$this->escapeString($this->dbName()).
+                       " and table_name=".$this->escapeString($this->tableName($tnm)));
                if($res===false)return false;
+               $ret=mysqli_num_rows($res)>0;
                mysqli_free_result($res);
-               return true;
+               return $ret;
        }
+
        public function beginTransaction()
        {
                WobTransaction::debug("DB Begin Transaction",WobTransaction::DebugDbTransaction);
@@ -187,6 +197,77 @@ class MysqlEngine extends DbEngine
                // one user of this function
                return $this->tableappend;
        }
+
+       protected function upgradeTable($tablename,$doexec)
+       {
+               $dbtn=$this->tableName($tablename);
+               $dbname=$this->dbName();
+               //get schema
+               $tschema=WobSchema::tableDefinition($tablename);
+               if($tschema===false){
+                       print("--  internal error: table does not exist in schema\n");
+                       return;
+               }
+               //get columns from DB
+               $res=mysqli_query($this->dbhdl,"select * from information_schema.columns where table_schema=".$this->escapeString($dbname).
+                       " and table_name=".$this->escapeString($dbtn)." order by ordinal_position");
+               if($res===false){
+                       print("<font color=\"red\">-- Internal error while querying table:".$this->lastError()."</font>\n");
+                       return;
+               }
+               $dbcols=mysqli_fetch_all($res,MYSQLI_ASSOC);
+               mysqli_free_result($res);
+               //go through columns
+               foreach($tschema as $cname=>$cdef){
+                       if(substr($cname,0,1)==":"){
+                               print("-- <font color=\"red\">special column ".$cname." IGNORING FOR NOW</font>\n");
+                               continue;
+                       }
+                       print("--  column ".$cname);
+                       // check column exists
+                       $ccol=array_values(array_filter($dbcols,function($col)use($cname){return $col["COLUMN_NAME"]==$cname;}));
+                       //print_r($ccol);
+                       if(count($ccol)<1){
+                               print(" ... does not exist\n");
+                               //create
+                               $stmt="ALTER TABLE ".$dbtn." ADD COLUMN ".$this->sqlCreateColumn($tablename,$cname,$cdef);
+                               print("<font color=\"green\">".$stmt.";</font>\n");
+                               if($doexec){
+                                       if(mysqli_query($this->dbhdl,$stmt)===false)
+                                               die("Unable to create column!");
+                               }
+                       }else{
+                               print(" ... exists, checking:\n");
+                               //check type is ok
+                               if($this->validateColumnType($cdef,$ccol[0]))
+                                       print("--   type ok\n");
+                               else{
+                                       print("--   adjusting type\n");
+                               }
+                       }
+               }
+       }
+
+       private function validateColumnType($schemadef,$dbdef)
+       {
+               // check type
+               $schematype=strtolower($this->dataType($schemadef[0]));
+               $dbtype=strtolower($dbdef["DATA_TYPE"]);
+               if($dbtype=="varchar")
+                       $dbtype=strtolower($dbdef["COLUMN_TYPE"]);
+               if(stristr($dbdef["EXTRA"],"auto_increment")!="")
+                       $dbtype.=" auto_increment";
+               if($schematype=="boolean")$schematype="tinyint";
+               if($schematype!=$dbtype){
+                       print("--    <font color=\"orange\">(type mismatch - schema: $schematype db: $dbtype)</font>\n");
+                       return false;
+               }else
+                       return true;
+               // check null
+               $schemanull=!in_array("notnull",$dbdef);
+               $dbnull=$dbdef["IS_NULLABLE"]=="YES";
+               return $schemanull==$dbnull;
+       }
        
        protected function tableName($tn)
        {
@@ -212,23 +293,25 @@ class MysqlEngine extends DbEngine
                return parent::dataType($type);
        }
        
-       protected function columnFlag($flag,$col,$table)
+       protected function columnFlag($flag,$col,$table,$cflags)
        {
                //MySQL does not mark columns for indexing directly, instead the index is appended to the table definition
-               if($flag=="index"){
+               if($flag=="index" && ($cflags&self::COLUMN_CREATE_INDEX)){
                        $this->tableappend.=", INDEX(".$col.")";
                        return "";
                }
                //MySQL::InnoDB is buggy, it accepts references only as appendix
-               $tpa=explode(":",$flag);
-               if($tpa[0]=="foreignkey"){
-                       if(count($tpa)<3)
-                               return false;
-                       $this->tableappend.=", FOREIGN KEY (".$col.") REFERENCES ".$this->tableName($tpa[1])."($tpa[2])";
-                       return "";
+               if($cflags&self::COLUMN_CREATE_FKEY){
+                       $tpa=explode(":",$flag);
+                       if($tpa[0]=="foreignkey"){
+                               if(count($tpa)<3)
+                                       return false;
+                               $this->tableappend.=", FOREIGN KEY (".$col.") REFERENCES ".$this->tableName($tpa[1])."($tpa[2])";
+                               return "";
+                       }
                }
                //fallback to SQL standard
-               return parent::columnFlag($flag,$col,$table);
+               return parent::columnFlag($flag,$col,$table,$cflags);
        }
        
        public function insert($table,array $values)
@@ -305,6 +388,18 @@ class MysqlEngine extends DbEngine
        }
 };
 
+
+//this function is often missing
+if(!function_exists('mysqli_fetch_all')){
+       function mysqli_fetch_all($result,$rtype=MYSQLI_NUM)
+       {
+               $ret=array();
+               mysqli_data_seek($result,0);
+               while(($tmp=mysqli_fetch_array($result, $rtype))!==null)$ret[]=$tmp;
+               return $ret;
+       }
+}
+
 //EOF
 return
 ?>
index d32d87a..f6cabaf 100644 (file)
@@ -1,5 +1,5 @@
 <?php
-// Copyright (C) 2009-2011 by Konrad Rosenbaum <konrad@silmor.de>
+// Copyright (C) 2009-2015 by Konrad Rosenbaum <konrad@silmor.de>
 // protected under the GNU LGPL version 3 or at your option any newer.
 // See COPYING.LGPL file that comes with this distribution.
 //
@@ -62,6 +62,11 @@ class PGsqlEngine extends DbEngine
                return $this->dbhdl!==false;
        }
 
+       public function dbName()
+       {
+               return pg_dbname($this->dbhdl);
+       }
+
        public function hasTable($tnm)
        {
                if(!WobSchema::hasTable($tnm))return false;
@@ -199,6 +204,85 @@ class PGsqlEngine extends DbEngine
                }else
                        return false;
        }
+
+       protected function upgradeTable($tablename,$doexec)
+       {
+               $dbtn=$this->tableName($tablename);
+               $dbname=$this->dbName();
+               //get schema
+               $tschema=WobSchema::tableDefinition($tablename);
+               if($tschema===false){
+                       print("--  internal error: table does not exist in schema\n");
+                       return;
+               }
+               //get columns from DB
+               $res=@pg_query($this->dbhdl,"select * from information_schema.columns where table_catalog=".$this->escapeString($dbname).
+                       " and table_name=".$this->escapeString($dbtn)." order by ordinal_position");
+               if($res===false){
+                       print("<font color=\"red\">-- Internal error while querying table:".$this->lastError()."</font>\n");
+                       return;
+               }
+               $dbcols=pg_fetch_all($res);
+               pg_free_result($res);
+               //print_r($dbcols);
+               //go through columns
+               foreach($tschema as $cname=>$cdef){
+                       if(substr($cname,0,1)==":"){
+                               print("-- <font color=\"red\">special column ".$cname." IGNORING FOR NOW</font>\n");
+                               continue;
+                       }
+                       print("--  column ".$cname);
+                       // check column exists
+                       $ccol=array_values(array_filter($dbcols,function($col)use($cname){return $col["column_name"]==$cname;}));
+                       //print_r($ccol);
+                       if(count($ccol)<1){
+                               print(" ... does not exist\n");
+                               //create
+                               $stmt="ALTER TABLE ".$dbtn." ADD COLUMN ".$this->sqlCreateColumn($tablename,$cname,$cdef);
+                               print("<font color=\"green\">".$stmt.";</font>\n");
+                               if($doexec){
+                                       if(@pg_query($this->dbhdl,$stmt)===false)
+                                               die("Unable to create column!");
+                               }
+                       }else{
+                               print(" ... exists, checking:\n");
+                               //check type is ok
+                               if($this->validateColumnType($cdef,$ccol[0]))
+                                       print("--   type ok\n");
+                               else{
+                                       print("--   adjusting type\n");
+                               }
+                       }
+               }
+       }
+
+       private function validateColumnType($schemadef,$dbdef)
+       {
+               //var_dump($dbdef);
+               // check type
+               $schematype=strtolower($this->dataType($schemadef[0]));
+               $dbtype=strtolower($dbdef["data_type"]);
+               if($dbtype=="character varying"){
+                       $dbtype="varchar";
+                       if($dbdef["character_maximum_length"]!=null)
+                               $dbtype.="(".$dbdef["character_maximum_length"].")";
+               }
+               if($schematype=="serial" || $schematype=="bigserial"){
+                       if(substr($dbdef["column_default"],0,8)=="nextval("){
+                               if($dbtype=="integer")$dbtype="serial";
+                               if($dbtype=="bigint")$dbtype="bigserial";
+                       }
+               }
+               if($schematype!=$dbtype){
+                       print("--    <font color=\"orange\">(type mismatch - schema: $schematype db: $dbtype)</font>\n");
+                       return false;
+               }else
+                       return true;
+               // check null
+               $schemanull=!in_array("notnull",$dbdef);
+               $dbnull=$dbdef["IS_NULLABLE"]=="YES";
+               return $schemanull==$dbnull;
+       }
        
        protected function sqlCreateTable($tn,$t)
        {