git-svn-id: https://svn.fournier38.fr/svn/ProgSVN/trunk@1621 bf3deb0d-5f1a-0410-827f-c0cc1f45334c
992 lines
34 KiB
PHP
992 lines
34 KiB
PHP
<?php
|
|
/** DomFramework
|
|
@package domframework
|
|
@author Dominique Fournier <dominique@fournier38.fr> */
|
|
|
|
// dblayer.php
|
|
|
|
/* Documentation :
|
|
The dbLayer provide an abstraction layer on PDO to be easier on all the CRUD
|
|
(Create, Read, Update, Delete) operations, accross all the databases engines.
|
|
To use it, extends in your code this class, and define the attributes :
|
|
- protected $table : name of the table you want to use
|
|
- protected $fields : description of all the fields in the database like :
|
|
protected $fields = array (
|
|
"id"=>array ("integer", "not null", "autoincrement"),
|
|
"zone"=>array ("varchar", "255", "not null"),
|
|
"viewname"=>array ("varchar", "255"),
|
|
"viewclients"=>array ("varchar", "255"),
|
|
"comment"=>array ("varchar", "1024"),
|
|
"opendate"=>array ("datetime", "not null"),
|
|
"closedate"=>array ("datetime"),
|
|
);
|
|
- protected $primary = "id" ; the primary key of the table (in text). Actually
|
|
the dbLayer abstraction don't supports primary key on multiples columns
|
|
- protected $unique = array ("column", array ("column1", "column2");)
|
|
|
|
Optionnaly, you can add the
|
|
- protected $debug = TRUE : enable the debug on screen (NOT FOR PROD !!)
|
|
*/
|
|
|
|
require_once ("domframework/verify.php");
|
|
|
|
/** Permit abstraction on the differents SQL databases available */
|
|
class dblayer extends PDO
|
|
{
|
|
/** The table name to use */
|
|
public $table = null;
|
|
/** The tableprefix text to prepend to table name (Should finish by _)
|
|
Just allow chars ! */
|
|
public $tableprefix = "";
|
|
/** The fields with the definition of type, and special parameters */
|
|
public $fields = array ();
|
|
/** The primary field */
|
|
public $primary = null;
|
|
/** An array to define the unique fields (or array of unique fields) */
|
|
public $unique = null;
|
|
/** An array to define the foreign keys of the field */
|
|
public $foreign = array ();
|
|
/** The db connection */
|
|
public $db = null;
|
|
/** The verify unitary stack
|
|
@param string $field The name of the field to test
|
|
@param string $val The value of the field to test */
|
|
public function verifyOne ($field, $val) {}
|
|
/** The verify global stack
|
|
@param array $datas The associative array of contents */
|
|
public function verifyAll ($datas) {}
|
|
/** Debug of the SQL */
|
|
public $debug = FALSE;
|
|
/** The connecting DSN */
|
|
private $dsn = null;
|
|
|
|
/** Return the connected database name from DSN used to connect */
|
|
public function databasename ()
|
|
{
|
|
if ($this->db === null)
|
|
throw new Exception (_("Database not connected"));
|
|
$vals = explode (";", substr (strstr ($this->dsn, ":"), 1));
|
|
$dsnExplode = array ();
|
|
foreach ($vals as $val)
|
|
{
|
|
@list ($k, $v) = explode ("=", $val);
|
|
$dsnExplode[$k] = $v;
|
|
}
|
|
if (isset ($dsnExplode["dbname"]))
|
|
return $dsnExplode["dbname"];
|
|
return NULL;
|
|
}
|
|
|
|
/** Return all the tables available in the database */
|
|
public function listTables ()
|
|
{
|
|
if ($this->db === null)
|
|
throw new Exception (_("Database not connected"));
|
|
switch ($this->db->getAttribute(PDO::ATTR_DRIVER_NAME))
|
|
{
|
|
case "sqlite":
|
|
$req = "SELECT name FROM sqlite_master WHERE type='table'";
|
|
$st = $this->db->prepare ($req);
|
|
$st->execute ();
|
|
$res = array ();
|
|
while ($d = $st->fetch (PDO::FETCH_ASSOC))
|
|
$res[] = $d["name"];
|
|
break;
|
|
case "mysql":
|
|
$req = "SELECT TABLE_NAME
|
|
FROM information_schema.tables
|
|
WHERE TABLE_SCHEMA='".$this->databasename()."'";
|
|
$st = $this->db->prepare ($req);
|
|
$st->execute ();
|
|
$res = array ();
|
|
while ($d = $st->fetch (PDO::FETCH_ASSOC))
|
|
$res[] = $d["TABLE_NAME"];
|
|
break;
|
|
case "pgsql":
|
|
$req = "SELECT *
|
|
FROM pg_tables
|
|
WHERE schemaname = 'public'";
|
|
$st = $this->db->prepare ($req);
|
|
$st->execute ();
|
|
$res = array ();
|
|
while ($d = $st->fetch (PDO::FETCH_ASSOC))
|
|
$res[] = $d["tablename"];
|
|
break;
|
|
default:
|
|
throw new Exception (_("Unknown database driver in listTables"));
|
|
}
|
|
return $res;
|
|
}
|
|
|
|
// TODO !!
|
|
/** Create Table creation from $this->fields with engine abstraction
|
|
Example in sqlite3 id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
in MySQL id INTEGER NOT NULL PRIMARY KEY AUTO_INCREMENT, */
|
|
|
|
// TODO !!
|
|
/** Create automatic creation of $fields from .schema of sqlite3/
|
|
show create table `NomTable`; for MySQL
|
|
SQLite3 : PRAGMA TABLE_INFO('yourtable');
|
|
MYSQL : SHOW COLUMNS FROM yourtable;*/
|
|
|
|
// TODO !!
|
|
/** Allow to modify tables if the definition is changed
|
|
Attention : SQLite don't supports adding Foreign keys without deleting all
|
|
the table, and re-import the datas (http://www.sqlite.org/omitted.html) */
|
|
|
|
/** Connection to the database engine
|
|
See http://fr2.php.net/manual/en/pdo.construct.php for the $dsn format
|
|
@param string $dsn PDO Data Source Name
|
|
@param string|null $username Username to connect
|
|
@param string|null $password Password to connect
|
|
@param string|null $driver_options Driver options to the database */
|
|
public function __construct ($dsn, $username=null, $password=null,
|
|
$driver_options=null)
|
|
{
|
|
try
|
|
{
|
|
$this->db = new PDO ($dsn, $username, $password, $driver_options);
|
|
$this->db->setAttribute (PDO::ATTR_ERRMODE, PDO::ERRMODE_EXCEPTION);
|
|
}
|
|
catch (Exception $e)
|
|
{
|
|
throw new Exception ("PDO error : ".$e->getMessage());
|
|
}
|
|
|
|
// Force specifics initialisations
|
|
switch ($this->db->getAttribute(PDO::ATTR_DRIVER_NAME))
|
|
{
|
|
case "sqlite":
|
|
// Look at the right to write in database and in the directory
|
|
$file = substr ($dsn, 7);
|
|
if (! is_writeable (dirname ($file)))
|
|
throw new Exception (
|
|
_("The directory for SQLite database is write protected"),
|
|
500);
|
|
if (file_exists ($file) && ! is_writeable ($file))
|
|
throw new Exception (_("The SQLite database file is write protected"),
|
|
500);
|
|
if (function_exists ("posix_getuid") &&
|
|
fileowner ($file) === posix_getuid ())
|
|
chmod ($file, 0666);
|
|
// Force ForeignKeys support (disabled by default)
|
|
$this->db->exec("PRAGMA foreign_keys = ON");
|
|
break;
|
|
}
|
|
$this->dsn = $dsn;
|
|
}
|
|
|
|
/** Create a new entry in the table. Datas must be an indexed array
|
|
@param array $datas Datas to be recorded (column=>value)
|
|
@obsolete 0.5 */
|
|
public function create ($datas)
|
|
{
|
|
return $this->insert ($datas);
|
|
}
|
|
|
|
/** Insert a new line of datas in the table. Datas must be an indexed array
|
|
@param array $datas Datas to be recorded (column=>value)*/
|
|
public function insert ($datas)
|
|
{
|
|
if ($this->db === null)
|
|
throw new Exception (_("Database not connected"), 500);
|
|
if ($this->unique === null)
|
|
throw new Exception (_("Unique fields of table are not defined"), 500);
|
|
if (!is_array ($datas))
|
|
throw new Exception (_("The datas provided to create are not array"),
|
|
405);
|
|
if (!in_array ($this->primary, $this->unique))
|
|
$this->unique[] = $this->primary;
|
|
$datasOK = array ();
|
|
// Check for missing parameters
|
|
foreach ($this->fields as $key=>$params)
|
|
{
|
|
if (in_array ("autoincrement", $params))
|
|
$datas[$key] = null;
|
|
if (in_array ("not null", $params) && !array_key_exists ($key, $datas))
|
|
throw new Exception (sprintf (_("Mandatory field '%s' not provided"),
|
|
$key), 405);
|
|
if (in_array ("not null", $params) && $datas[$key] === "")
|
|
throw new Exception (sprintf (_("Mandatory field '%s' is empty"),
|
|
$key), 405);
|
|
if (!array_key_exists ($key, $datas))
|
|
continue;
|
|
// Verify the fields, if $verify is defined, before doing insertion
|
|
$verify = $this->verifyOne ($key, $datas[$key]);
|
|
if (is_array ($verify) && count ($verify))
|
|
throw new Exception ($verify[0]." ".$verify[1]." in ".$key);
|
|
// Check for type inconsistencies if the value is provided
|
|
if ($datas[$key] !== "" && $params[0] === "integer")
|
|
{
|
|
if (strspn ($datas[$key], "0123456789") !== strlen ($datas[$key]))
|
|
throw new Exception (sprintf (
|
|
_("Errors in consistency : '%s' is not an integer"),
|
|
$key), 405);
|
|
}
|
|
elseif ($datas[$key] !== "" && $params[0] === "varchar")
|
|
{
|
|
if (! isset ($params[1]))
|
|
throw new Exception (sprintf (
|
|
_("The length of varchar field '%s' is not provided"),
|
|
$key), 500);
|
|
if (strlen ($datas[$key]) > $params[1])
|
|
throw new Exception (sprintf (
|
|
_("Errors in consistency : '%s' data is too long"),
|
|
$key), 405);
|
|
}
|
|
elseif ($datas[$key] !== "" && $params[0] === "datetime")
|
|
{
|
|
// The date format must be in ANSI SQL : YYYY-MM-DD HH:MM:SS
|
|
$d = DateTime::createFromFormat("Y-m-d H:i:s", $datas[$key]);
|
|
if (!$d || $d->format("Y-m-d H:i:s") !== $datas[$key])
|
|
throw new Exception (sprintf (
|
|
_("Incorrect datetime provided for field '%s'"),
|
|
$key), 500);
|
|
}
|
|
elseif ($datas[$key] !== "" && $params[0] === "date")
|
|
{
|
|
// The date format must be in ANSI SQL : YYYY-MM-DD
|
|
$d = DateTime::createFromFormat("Y-m-d", $datas[$key]);
|
|
if (!$d || $d->format("Y-m-d") !== $datas[$key])
|
|
throw new Exception (sprintf (
|
|
_("Incorrect date provided for field '%s'"),
|
|
$key), 500);
|
|
}
|
|
elseif ($datas[$key] !== "")
|
|
throw new Exception (sprintf (_("Unknown field type for '%s'"), $key),
|
|
500);
|
|
else
|
|
{
|
|
// Nothing to do if the value is empty : just save it
|
|
}
|
|
$datasOK[$key] = $datas[$key];
|
|
}
|
|
|
|
// Check for inconsistency
|
|
$verify = $this->verifyAll ($datas);
|
|
if (count ($verify))
|
|
throw new Exception (_("Errors in consistency : ").
|
|
print_r ($verify, TRUE), 405);
|
|
|
|
// Check if the unique constrain is valid before doing the insertion
|
|
foreach ($this->unique as $columns)
|
|
{
|
|
if (is_array ($columns))
|
|
{
|
|
$select = array ();
|
|
foreach ($columns as $col)
|
|
{
|
|
if (!array_key_exists ($col, $datasOK)) continue;
|
|
$select[] = array ($col, $datasOK[$col]);
|
|
}
|
|
$rc = $this->read ($select, array ($this->primary));
|
|
if (count ($rc) > 0)
|
|
throw new Exception (sprintf (
|
|
_("The provided values for columns '%s' already exists"),
|
|
implode (",", $columns)), 405);
|
|
}
|
|
else
|
|
{
|
|
if (!array_key_exists ($columns, $datasOK)) continue;
|
|
$rc = $this->read (array (array ($columns, $datasOK[$columns])),
|
|
array ($this->primary));
|
|
if (count ($rc) > 0)
|
|
throw new Exception (sprintf (
|
|
_("The column '%s' with this value already exists"),
|
|
$columns), 405);
|
|
}
|
|
}
|
|
|
|
// Check if the foreign keys constrains are valid before doing the insertion
|
|
foreach ($this->foreign as $foreign=>$data)
|
|
{
|
|
$table = $data[0];
|
|
$column = $data[1];
|
|
$req = "SELECT $column FROM `$this->tableprefix$table` ".
|
|
"WHERE $column=:$column";
|
|
if ($this->debug) echo "DEBUG : $req\n";
|
|
$st = $this->db->prepare ($req);
|
|
$val = $datasOK[$foreign];
|
|
$key = $column;
|
|
if ($this->debug) echo "DEBUG BIND : $column->".var_export ($val, TRUE).
|
|
"\n";
|
|
if ($val === null)
|
|
$st->bindValue (":$key", $val, PDO::PARAM_NULL);
|
|
elseif ($this->fields[$key][0] === "integer")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_INT);
|
|
elseif ($this->fields[$key][0] === "varchar")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
elseif ($this->fields[$key][0] === "datetime")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
elseif ($this->fields[$key][0] === "date")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
else
|
|
throw new Exception ("TO BE DEVELOPPED : ".$this->fields[$key][0], 500);
|
|
$st->execute ();
|
|
$res = array ();
|
|
while ($d = $st->fetch (PDO::FETCH_ASSOC))
|
|
$res[] = $d;
|
|
if (count ($res) === 0)
|
|
throw new Exception (sprintf (_("The foreign key '%s' doesn't exists"),
|
|
$column), 405);
|
|
}
|
|
|
|
$req = "INSERT INTO `$this->tableprefix$this->table` ";
|
|
$req .= "(".implode (",", array_keys ($datasOK)).")";
|
|
$req .= " VALUES ";
|
|
$req .= "(:".implode (",:", array_keys ($datasOK)).")";
|
|
if ($this->debug) echo "DEBUG : $req\n";
|
|
$st = $this->db->prepare ($req);
|
|
foreach ($datasOK as $key=>$val)
|
|
{
|
|
if ($this->debug) echo "DEBUG BIND : $key->".var_export ($val, TRUE)."\n";
|
|
if ($val === null)
|
|
$st->bindValue (":$key", $val, PDO::PARAM_NULL);
|
|
elseif ($this->fields[$key][0] === "integer")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_INT);
|
|
elseif ($this->fields[$key][0] === "varchar")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
elseif ($this->fields[$key][0] === "datetime")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
elseif ($this->fields[$key][0] === "date")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
else
|
|
throw new Exception ("TO BE DEVELOPPED : ".$this->fields[$key][0], 500);
|
|
}
|
|
|
|
$st->execute ();
|
|
return $this->db->lastInsertId();
|
|
}
|
|
|
|
/** Read the table content based on a select filter, ordered by order
|
|
operator and the associated select value
|
|
@param array|null $select Rows to select with
|
|
$select = array (array ($key, $val, $operator), ...)
|
|
$key=>column, $val=>value to found, $operator=>'LIKE', =...
|
|
@param array|null $display Columns displayed
|
|
$display = array ($col1, $col2...);
|
|
@param array|null $order Sort the columns by orientation
|
|
$order = array (array ($key, $orientation), ...)
|
|
$key=>column, $orientation=ASC/DESC */
|
|
public function read ($select=null, $display=null, $order=null)
|
|
{
|
|
if ($this->db === null)
|
|
throw new Exception (_("Database not connected"), 500);
|
|
if ($select !== null && !is_array ($select))
|
|
throw new Exception (_("Select information provided is not an array"),
|
|
405);
|
|
if ($display !== null && !is_array ($display))
|
|
throw new Exception (_("Display information provided is not an array"),
|
|
405);
|
|
if ($order !== null && !is_array ($order))
|
|
throw new Exception (_("Order information provided is not an array"),
|
|
405);
|
|
if ($display !== null)
|
|
{
|
|
foreach ($display as $f)
|
|
{
|
|
if (!in_array ($f, array_keys ($this->fields)))
|
|
throw new Exception (sprintf (_("Field '%s' not allowed"), $f), 506);
|
|
}
|
|
}
|
|
else
|
|
{
|
|
$display = array_keys ($this->fields);
|
|
}
|
|
|
|
$req = "SELECT ";
|
|
$req .= implode (",", $display);
|
|
$req .= " FROM `$this->tableprefix$this->table`";
|
|
if ($select !== null)
|
|
{
|
|
$req .= " WHERE ";
|
|
foreach ($select as $n=>$s)
|
|
{
|
|
if ($n > 0)
|
|
$req .= " AND";
|
|
if (!isset ($s[2]))
|
|
$s[2] = "=";
|
|
$req .= " ".$s[0]." ".$s[2]." :".$s[0];
|
|
}
|
|
}
|
|
|
|
if ($order !== null)
|
|
{
|
|
$req .= " ORDER BY ";
|
|
foreach ($order as $n=>$o)
|
|
{
|
|
if ($n > 0)
|
|
$req .= ",";
|
|
$req .= $o[0];
|
|
if (isset ($o[1]) && $o[1] === "DESC")
|
|
$req .= " DESC";
|
|
else
|
|
$req .= " ASC";
|
|
}
|
|
}
|
|
|
|
if ($this->debug) echo "DEBUG : $req\n";
|
|
$st = $this->db->prepare ($req);
|
|
if ($select !== NULL)
|
|
{
|
|
foreach ($select as $s)
|
|
{
|
|
if ($this->debug) echo "DEBUG BIND : ".$s[0]."->".
|
|
var_export ($s[1], TRUE)."\n";
|
|
$st->bindValue (":".$s[0], $s[1]);
|
|
}
|
|
}
|
|
|
|
$st->execute ();
|
|
$res = array ();
|
|
while ($d = $st->fetch (PDO::FETCH_ASSOC))
|
|
$res[] = $d;
|
|
return $res;
|
|
}
|
|
|
|
/** Update the key tuple with the provided datas
|
|
Return the number of rows modified
|
|
@param string|integer $updatekey The key applied on primary key to be
|
|
updated
|
|
@param array $datas The values to be updated */
|
|
public function update ($updatekey, $datas)
|
|
{
|
|
if ($this->db === null)
|
|
throw new Exception (_("Database not connected"), 500);
|
|
$datasOK = array ();
|
|
// Check for missing parameters
|
|
foreach ($this->fields as $key=>$params)
|
|
{
|
|
// Verify the fields, if $verify is defined, before doing insertion
|
|
if (array_key_exists ($key, $datas))
|
|
$datasOK[$key] = $datas[$key];
|
|
}
|
|
if (count ($datasOK) === 0)
|
|
throw new Exception (_("Don't receive any field to display"), 501);
|
|
|
|
// Check for type inconsistencies before using $datasOK
|
|
foreach ($datasOK as $key=>$params)
|
|
{
|
|
$verify = $this->verifyOne ($key, $datas[$key]);
|
|
if (is_array ($verify) && count ($verify))
|
|
throw new Exception ($verify[0]." ".$verify[1]." in ".$key);
|
|
}
|
|
|
|
// Check if the unique constrain is valid before doing the insertion
|
|
// 1. Read the actual state
|
|
$before = $this->read (array (array ($this->primary, $updatekey)));
|
|
if (count ($before) === 0)
|
|
throw new Exception (_("Entry to modify unavailable"), 404);
|
|
$before = reset ($before);
|
|
// 2. Map the proposal entries into the before state
|
|
$after = $before;
|
|
foreach ($datasOK as $field=>$val)
|
|
$after[$field] = $val;
|
|
// 3. Check for constrain violation on unique columns
|
|
foreach ($this->unique as $columns)
|
|
{
|
|
if (is_array ($columns))
|
|
{
|
|
// Multiple columns in unique
|
|
$select = array ();
|
|
$select[] = array ($this->primary, $updatekey, "!=");
|
|
foreach ($columns as $col)
|
|
{
|
|
if (!array_key_exists ($col, $after)) continue;
|
|
$select[] = array ($col, $after[$col]);
|
|
}
|
|
|
|
// If there is only the primary key, there is no chance to have a
|
|
// conflict
|
|
if (count ($select) >= 2)
|
|
{
|
|
$rc = $this->read ($select, array ($this->primary));
|
|
if (count ($rc) > 0)
|
|
throw new Exception (sprintf (
|
|
_("The provided values for columns '%s' already exists"),
|
|
implode (",", $columns)), 405);
|
|
}
|
|
}
|
|
else
|
|
{
|
|
// One column in unique
|
|
if (!array_key_exists ($columns, $datasOK)) continue;
|
|
$select = array ();
|
|
if ($columns === $this->primary)
|
|
$select[] = array ($this->primary, $updatekey, "!=");
|
|
$select[] = array ($columns, $datasOK[$columns]);
|
|
$rc = $this->read ($select,
|
|
array ($this->primary));
|
|
if (count ($rc) > 0)
|
|
throw new Exception (sprintf (
|
|
_("An entry already exists with this value in the column '%s'"),
|
|
$columns), 405);
|
|
}
|
|
}
|
|
|
|
// Check if the foreign keys constrains are valid before doing the update
|
|
foreach ($this->foreign as $foreign=>$data)
|
|
{
|
|
// If the foreign keys are not modified, we don't check if they are
|
|
// correct
|
|
if (!isset ($datasOK[$foreign]))
|
|
continue;
|
|
$table = $data[0];
|
|
$column = $data[1];
|
|
$req = "SELECT $column FROM `$this->tableprefix$table` ".
|
|
"WHERE $column=:$column";
|
|
if ($this->debug) echo "DEBUG : $req\n";
|
|
$st = $this->db->prepare ($req);
|
|
$val = $datasOK[$foreign];
|
|
$key = $column;
|
|
if ($this->debug) echo "DEBUG BIND : $column->".var_export ($val, TRUE).
|
|
"\n";
|
|
if ($val === null)
|
|
$st->bindValue (":$key", $val, PDO::PARAM_NULL);
|
|
elseif ($this->fields[$key][0] === "integer")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_INT);
|
|
elseif ($this->fields[$key][0] === "varchar")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
elseif ($this->fields[$key][0] === "datetime")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
elseif ($this->fields[$key][0] === "date")
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
else
|
|
throw new Exception ("TO BE DEVELOPPED : ".$this->fields[$key][0], 500);
|
|
$st->execute ();
|
|
$res = array ();
|
|
while ($d = $st->fetch (PDO::FETCH_ASSOC))
|
|
$res[] = $d;
|
|
if (count ($res) === 0)
|
|
throw new Exception (sprintf (_("The foreign key '%s' doesn't exists"),
|
|
$column), 405);
|
|
}
|
|
|
|
$datasOK[$this->primary] = $updatekey;
|
|
$req = "UPDATE `".$this->tableprefix."$this->table` SET ";
|
|
$i = 0;
|
|
foreach ($datasOK as $key=>$val)
|
|
{
|
|
if ($i>0) $req .= ",";
|
|
$req .= "$key=:$key";
|
|
$i++;
|
|
}
|
|
|
|
$req .= " WHERE $this->primary=:$this->primary";
|
|
if ($this->debug) echo "DEBUG : $req\n";
|
|
$st = $this->db->prepare ($req);
|
|
foreach ($datasOK as $key=>$val)
|
|
{
|
|
if ($this->debug) echo "DEBUG BIND : $key->".var_export ($val, TRUE)." ";
|
|
if ($val === null)
|
|
{
|
|
if ($this->debug) echo "(null)\n";
|
|
$st->bindValue (":$key", $val, PDO::PARAM_NULL);
|
|
}
|
|
elseif ($this->fields[$key][0] === "integer")
|
|
{
|
|
if ($this->debug) echo "(integer)\n";
|
|
$st->bindValue (":$key", $val, PDO::PARAM_INT);
|
|
}
|
|
elseif ($this->fields[$key][0] === "varchar")
|
|
{
|
|
if ($this->debug) echo "(varchar)\n";
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
}
|
|
elseif ($this->fields[$key][0] === "datetime")
|
|
{
|
|
if ($this->debug) echo "(datetime)\n";
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
}
|
|
elseif ($this->fields[$key][0] === "date")
|
|
{
|
|
if ($this->debug) echo "(date)\n";
|
|
$st->bindValue (":$key", $val, PDO::PARAM_STR);
|
|
}
|
|
else
|
|
{
|
|
if ($this->debug) echo "(UNKNOWN)\n";
|
|
throw new Exception ("TO BE DEVELOPPED : ".$this->fields[$key][0], 500);
|
|
}
|
|
}
|
|
|
|
$st->execute ();
|
|
return $st->rowCount ();
|
|
}
|
|
|
|
/** Delete a tuple identified by its primary key
|
|
Return the number of deleted rows (can be 0 !)
|
|
@param strin|integer $deletekey The key of primary key to be deleted */
|
|
public function delete ($deletekey)
|
|
{
|
|
if ($this->db === null)
|
|
throw new Exception (_("Database not connected"));
|
|
$req = "DELETE FROM `$this->tableprefix$this->table` ";
|
|
$req .= "WHERE $this->primary = :primary";
|
|
$st = $this->db->prepare ($req);
|
|
if ($this->debug) echo "DEBUG : $req\n";
|
|
if ($this->debug) echo "DEBUG BIND : primary->".
|
|
var_export ($deletekey, TRUE)."\n";
|
|
$st->bindValue (":primary", $deletekey);
|
|
$st->execute ();
|
|
return $st->rowCount();
|
|
}
|
|
|
|
/** Translation of fields */
|
|
public function titles ()
|
|
{
|
|
$arr = array ();
|
|
foreach ($this->fields as $field=>$v)
|
|
$arr[$field] = $field;
|
|
return $arr;
|
|
}
|
|
|
|
/** Create the table defined by the differents fields.
|
|
Define the SQL syntax based on SQL engines
|
|
$table = "dns zones";
|
|
$fields = array (
|
|
"id"=>array ("integer", "not null", "autoincrement"),
|
|
"zo ne"=>array ("varchar", "255", "not null"),
|
|
"vie wname"=>array ("varchar", "255"),
|
|
"view clients"=>array ("varchar", "255"),
|
|
"comme nt"=>array ("varchar", "1024"),
|
|
"opendate"=>array ("datetime", "not null"),
|
|
"closedate"=>array ("datetime"),
|
|
);
|
|
$primary = "id";
|
|
$unique = array ("id", array ("zo ne", "vie wname"));
|
|
$foreign = array ("zone"=>"table.field",...);
|
|
*/
|
|
public function createTable ()
|
|
{
|
|
if ($this->db === null)
|
|
throw new Exception (_("Database not connected"));
|
|
switch ($this->db->getAttribute(PDO::ATTR_DRIVER_NAME))
|
|
{
|
|
case "sqlite":
|
|
$sql = "CREATE TABLE `$this->tableprefix$this->table` (\n";
|
|
$i = 0;
|
|
foreach ($this->fields as $field=>$params)
|
|
{
|
|
if ($i > 0)
|
|
$sql .= ",\n";
|
|
// Name of field
|
|
$sql .= "`$field` ";
|
|
// Type of field : in $params[0]
|
|
if (!isset ($params[0]))
|
|
throw new Exception (sprintf (
|
|
_("No database type defined for field '%s'"),
|
|
$field), 500);
|
|
|
|
switch ($params[0])
|
|
{
|
|
case "integer":
|
|
$sql .= "INTEGER";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
case "varchar":
|
|
if (!isset ($params[1]))
|
|
throw new Exception (_("No Size provided for varchar field"));
|
|
$sql .= "VARCHAR(".$params[1].")";
|
|
$params = array_slice ($params, 2);
|
|
break;
|
|
case "datetime":
|
|
$sql .= "DATETIME";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
case "date":
|
|
$sql .= "DATE";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
default:
|
|
throw new Exception (sprintf (
|
|
_("Unknown type '%s' provided for field '%s'"),
|
|
$params[0], $field), 500);
|
|
}
|
|
// Primary key
|
|
if ($this->primary === $field)
|
|
$sql .= " PRIMARY KEY";
|
|
// Others parameters for field
|
|
// Sort to put the autoincrement field in front of params, if it is
|
|
// present
|
|
sort ($params);
|
|
foreach ($params as $p)
|
|
{
|
|
switch ($p)
|
|
{
|
|
case "not null": $sql .= " NOT NULL"; break;
|
|
case "autoincrement": $sql .= " AUTOINCREMENT";break;
|
|
default:
|
|
throw new Exception (_("Unknown additionnal parameter for field"),
|
|
500);
|
|
}
|
|
}
|
|
$i ++;
|
|
}
|
|
// Unique fields
|
|
if ($this->unique !== null)
|
|
{
|
|
if (!is_array ($this->unique))
|
|
throw new Exception (
|
|
_("The Unique field definition is not an array"));
|
|
foreach ($this->unique as $u)
|
|
{
|
|
$sql .= ",\n UNIQUE (`";
|
|
if (is_array ($u))
|
|
$sql .=implode ("`,`", $u);
|
|
else
|
|
$sql .= $u;
|
|
$sql .="`)";
|
|
}
|
|
}
|
|
// Foreign keys
|
|
$i = 0;
|
|
foreach ($this->foreign as $field=>$k)
|
|
{
|
|
$sql .= ",\n FOREIGN KEY(`$field`) REFERENCES `".$k[0]."`(`".
|
|
$k[1]."`)";
|
|
if (isset ($k[2]))
|
|
$sql .= " ".$k[2];
|
|
if ($i > 0)
|
|
$sql .= ",";
|
|
$i++;
|
|
}
|
|
$sql .=")";
|
|
break;
|
|
case "mysql":
|
|
$sql = "CREATE TABLE `$this->tableprefix$this->table` (\n";
|
|
$i = 0;
|
|
foreach ($this->fields as $field=>$params)
|
|
{
|
|
if ($i > 0)
|
|
$sql .= ",\n";
|
|
// Name of field
|
|
$sql .= "`$field` ";
|
|
// Type of field : in $params[0]
|
|
if (!isset ($params[0]))
|
|
throw new Exception (_("No database type defined for field"));
|
|
switch ($params[0])
|
|
{
|
|
case "integer":
|
|
$sql .= "INTEGER";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
case "varchar":
|
|
if (!isset ($params[1]))
|
|
throw new Exception (_("No Size provided for varchar field"));
|
|
$sql .= "VARCHAR(".$params[1].")";
|
|
$params = array_slice ($params, 2);
|
|
break;
|
|
case "datetime":
|
|
$sql .= "DATETIME";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
case "date":
|
|
$sql .= "DATE";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
default:
|
|
throw new Exception (sprintf (
|
|
_("Unknown type provided for field '%s'"),
|
|
$field), 500);
|
|
}
|
|
// Primary key
|
|
if ($this->primary === $field)
|
|
$sql .= " PRIMARY KEY";
|
|
// Others parameters for field
|
|
// Sort to put the autoincrement field in front of params, if it is
|
|
// present
|
|
sort ($params);
|
|
foreach ($params as $p)
|
|
{
|
|
switch ($p)
|
|
{
|
|
case "not null": $sql .= " NOT NULL"; break;
|
|
case "autoincrement": $sql .= " AUTO_INCREMENT";break;
|
|
default:
|
|
throw new Exception (sprintf (
|
|
_("Unknown additionnal parameter for field '%s'"),
|
|
$field), 500);
|
|
}
|
|
}
|
|
$i ++;
|
|
}
|
|
// Unique fields
|
|
if ($this->unique !== null)
|
|
{
|
|
foreach ($this->unique as $u)
|
|
{
|
|
$sql .= ",\n UNIQUE (`";
|
|
if (is_array ($u))
|
|
$sql .=implode ("`,`", $u);
|
|
else
|
|
$sql .= $u;
|
|
$sql .="`)";
|
|
}
|
|
}
|
|
// Foreign keys
|
|
$i = 0;
|
|
foreach ($this->foreign as $field=>$k)
|
|
{
|
|
|
|
$sql .= ",\n FOREIGN KEY(`$field`) REFERENCES `".$k[0]."`(`".
|
|
$k[1]."`)";
|
|
if (isset ($k[2]))
|
|
$sql .= " ".$k[2];
|
|
if ($i > 0)
|
|
$sql .= ",";
|
|
$i++;
|
|
}
|
|
$sql .=") ENGINE=InnoDB DEFAULT CHARSET=utf8;";
|
|
break;
|
|
case "pgsql":
|
|
$sql = "CREATE TABLE \"$this->tableprefix$this->table\" (\n";
|
|
$i = 0;
|
|
foreach ($this->fields as $field=>$params)
|
|
{
|
|
if ($i > 0)
|
|
$sql .= ",\n";
|
|
// Name of field
|
|
$sql .= "\"$field\" ";
|
|
if (in_array ("autoincrement", $params))
|
|
$sql .= "SERIAL";
|
|
else
|
|
{
|
|
// Type of field : in $params[0]
|
|
if (!isset ($params[0]))
|
|
throw new Exception (sprintf (
|
|
_("No database type defined for field '%s'"),
|
|
$field), 500);
|
|
switch ($params[0])
|
|
{
|
|
case "integer":
|
|
$sql .= "INTEGER";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
case "varchar":
|
|
if (!isset ($params[1]))
|
|
throw new Exception (sprintf (
|
|
_("No Size provided for varchar field '%s'"),
|
|
$field), 500);
|
|
$sql .= "VARCHAR(".$params[1].")";
|
|
$params = array_slice ($params, 2);
|
|
break;
|
|
case "datetime":
|
|
$sql .= "timestamp with time zone";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
case "date":
|
|
$sql .= "DATE";
|
|
$params = array_slice ($params, 1);
|
|
break;
|
|
default:
|
|
throw new Exception (sprintf (
|
|
_("Unknown type provided for field '%s'"),
|
|
$field), 500);
|
|
}
|
|
// Primary key
|
|
if ($this->primary === $field)
|
|
$sql .= " PRIMARY KEY";
|
|
// Others parameters for field
|
|
// Sort to put the autoincrement field in front of params, if it is
|
|
// present
|
|
sort ($params);
|
|
foreach ($params as $p)
|
|
{
|
|
switch ($p)
|
|
{
|
|
case "not null": $sql .= " NOT NULL"; break;
|
|
default:
|
|
throw new Exception (sprintf (
|
|
_("Unknown additionnal parameter for field '%s'"),
|
|
$field), 500);
|
|
}
|
|
}
|
|
}
|
|
$i ++;
|
|
}
|
|
// Unique fields
|
|
if ($this->unique !== null)
|
|
{
|
|
foreach ($this->unique as $u)
|
|
{
|
|
$sql .= ",\n UNIQUE (\"";
|
|
if (is_array ($u))
|
|
$sql .=implode ("\",\"", $u);
|
|
else
|
|
$sql .= $u;
|
|
$sql .="\")";
|
|
}
|
|
}
|
|
// Foreign keys
|
|
$i = 0;
|
|
foreach ($this->foreign as $field=>$k)
|
|
{
|
|
$sql .= ",\n FOREIGN KEY(\"$field\") REFERENCES \"".$k[0]."\"(\"".
|
|
$k[1]."\")";
|
|
if (isset ($k[2]))
|
|
$sql .= " ".$k[2];
|
|
if ($i > 0)
|
|
$sql .= ",";
|
|
$i++;
|
|
}
|
|
$sql .=")";
|
|
break;
|
|
default:
|
|
throw new Exception (_("PDO Engine not supported in dbLayer"), 500);
|
|
}
|
|
|
|
if ($this->debug)
|
|
echo "$sql\n";
|
|
return $this->db->exec($sql);
|
|
}
|
|
|
|
/** This function permit to send a SQL request to the database to do a SELECT
|
|
Return the an array with the datas */
|
|
public function directRead ($sql)
|
|
{
|
|
$st = $this->db->prepare ($sql);
|
|
$st->execute ();
|
|
$res = array ();
|
|
while ($d = $st->fetch (PDO::FETCH_ASSOC))
|
|
$res[] = $d;
|
|
return $res;
|
|
}
|
|
}
|
|
|
|
/** POC :
|
|
error_reporting (E_ALL);
|
|
require_once ("domframework/dbLayer.php");
|
|
class zone extends dbLayer
|
|
{
|
|
// The database must be initialized with
|
|
// CREATE TABLE `dns_zones` (id INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT,
|
|
// zone VARCHAR(255) NOT NULL,
|
|
// viewname VARCHAR(255),
|
|
// viewclients VARCHAR(255),
|
|
// comment VARCHAR(1024),
|
|
// opendate DATETIME NOT NULL,
|
|
// closedate DATETIME,
|
|
// UNIQUE (zone,viewname));
|
|
protected $table = "dns_zones";
|
|
protected $fields = array (
|
|
"id"=>array ("integer", "not null", "autoincrement"),
|
|
"zone"=>array ("varchar", "255", "not null"),
|
|
"viewname"=>array ("varchar", "255"),
|
|
"viewclients"=>array ("varchar", "255"),
|
|
"comment"=>array ("varchar", "1024"),
|
|
"opendate"=>array ("datetime", "not null"),
|
|
"closedate"=>array ("datetime"),
|
|
);
|
|
protected $primary = "id";
|
|
protected $unique = array ("id", array ("zone", "viewname"));
|
|
}
|
|
|
|
ini_set ("date.timezone", "Europe/Paris");
|
|
$zone = new zone ("sqlite:datas/database.db");
|
|
$last = $zone->create (array ("zone"=>"testZone", "opendate"=>date("Y-m-d H:i:s")));
|
|
//print_r ($zone->read ());
|
|
$zone->update (2040, array ("zone"=>"testZone2"));
|
|
print_r ($zone->delete ($last));
|
|
*/
|