From 5c4f9039875536e3dcb88a219c37faed58825382 Mon Sep 17 00:00:00 2001 From: Dominique Fournier Date: Mon, 27 Mar 2017 07:42:18 +0000 Subject: [PATCH] * dblayeroo : add a new dblayer class. More OO, supports more options than dblayer * fts : The Full Text Search module for dummies git-svn-id: https://svn.fournier38.fr/svn/ProgSVN/trunk@3459 bf3deb0d-5f1a-0410-827f-c0cc1f45334c --- Tests/autoload.php.dist | 10 + Tests/dblayerooComplet.php | 363 +++++++ Tests/ftsTest.php | 174 +++ dblayeroo.php | 2107 ++++++++++++++++++++++++++++++++++++ fts.php | 222 ++++ 5 files changed, 2876 insertions(+) create mode 100644 Tests/dblayerooComplet.php create mode 100644 Tests/ftsTest.php create mode 100644 dblayeroo.php create mode 100644 fts.php diff --git a/Tests/autoload.php.dist b/Tests/autoload.php.dist index 5c7feb5..c56d6b8 100644 --- a/Tests/autoload.php.dist +++ b/Tests/autoload.php.dist @@ -6,6 +6,16 @@ spl_autoload_register(function ($class) { define ("PHPUNIT", "ON-GOING"); + +file_put_contents ("Tests/dblayerooSqliteTest.php", + str_replace ("{ENGINE}", "sqlite", + file_get_contents ("Tests/dblayerooComplet.php"))); +file_put_contents ("Tests/dblayerooMySQLTest.php", + str_replace ("{ENGINE}", "mysql", + file_get_contents ("Tests/dblayerooComplet.php"))); +file_put_contents ("Tests/dblayerooPostgreSQLTest.php", + str_replace ("{ENGINE}", "pgsql", + file_get_contents ("Tests/dblayerooComplet.php"))); file_put_contents ("Tests/dblayerSqliteTest.php", str_replace ("{ENGINE}", "sqlite", file_get_contents ("Tests/dblayerComplet.php"))); diff --git a/Tests/dblayerooComplet.php b/Tests/dblayerooComplet.php new file mode 100644 index 0000000..571945d --- /dev/null +++ b/Tests/dblayerooComplet.php @@ -0,0 +1,363 @@ + */ + +class test_dblayeroo_{ENGINE} extends PHPUnit_Framework_TestCase +{ +// Test with column name 'group', 'object', 'where', 'with space' +// Test with table name 'group', 'object', 'where', 'with space' +// For the 3 DB engines + + public $engine="{ENGINE}"; + public $confs = array ( + "sqlite" => array ( + "dsn" => "sqlite:/tmp/databaseDBLayeroo.db", + "username" => null, + "password" => null, + "driver_options" => null, + "tableprefix" => "", + ), + "mysql" => array ( + "dsn" => "mysql:host=127.0.0.1;port=3306;dbname=test", + "username" => "root", + "password" => "lqsym", + "driver_options" => null, + "tableprefix" => "", + ), + "pgsql" => array ( + "dsn" => "pgsql:host=127.0.0.1;port=5432;dbname=dbname", + "username" => "root", + "password" => "root", + "driver_options" => null, + "tableprefix" => "", + ), + ); + + private function db1 () + { + $dbconfig = $this->confs["{ENGINE}"]; + $db1 = new dblayeroo ($dbconfig["dsn"], $dbconfig["username"], + $dbconfig["password"], $dbconfig["driver_options"]); + $db1->table ("groupedoo"); + $db1->fields (array ("group"=>array ("varchar(255)", "not null"), + "object"=>array ("varchar(255)", "not null"), + "where"=>array ("varchar(255)", "not null"), + "with space"=>array ("varchar(255)"))); + $db1->unique (array ()); + $db1->primary ("group"); + return $db1; + } + + private function db2 () + { + $dbconfig = $this->confs["{ENGINE}"]; + $db2 = new dblayeroo ($dbconfig["dsn"], $dbconfig["username"], + $dbconfig["password"], $dbconfig["driver_options"]); + $db2->table ("usersoo"); + $db2->fields (array ("uid"=>array ("integer", "not null", "autoincrement"), + "gecos"=>array ("varchar(255)", "not null"), + "password"=>array ("varchar(255)", "not null"), + "group" => array ("varchar(255)", "not null"), + )); + $db2->unique (array ("gecos","password")); + $db2->primary ("uid"); + $db2->foreign (array ("group" => array ("groupedoo", "group", "ON DELETE CASCADE"))); + return $db2; + } + + private function db3 () + { + $dbconfig = $this->confs["{ENGINE}"]; + $db3 = new dblayeroo ($dbconfig["dsn"], $dbconfig["username"], + $dbconfig["password"], $dbconfig["driver_options"]); + return $db3; + } + + public function test_dropTable () + { + $dbconfig = $this->confs["{ENGINE}"]; + $db = new dblayeroo ($dbconfig["dsn"], $dbconfig["username"], + $dbconfig["password"], $dbconfig["driver_options"]); + foreach (array ("usersoo", "groupedoo", "multipleoo", "multiple2oo", "users3oo", + "readORoo") as + $table) + { + $db->table ($table); + try + { + $res = $db->dropTable(); + } + catch (Exception $e) + { + } + } + $db->disconnect (); + // Never generate an error, just drop the table if it exists, and do noting + // if it doesn't exists + } + + public function test_createTable1 () + { + // Create a table named groupedoo + $db1 = $this->db1 (); + $res = $db1->createTable (); + $db1->disconnect (); + $this->assertSame (0, $res); + } + + public function test_createTable2 () + { + // Create a table named usersoo + $db2 = $this->db2 (); + $res = $db2->createTable (); + $db2->disconnect (); + $this->assertSame (0, $res); + } + + public function test_select1 () + { + // Select all on the table : nothing + $db1 = $this->db1 (); + $res = $db1->select()->execute (); + $db1->disconnect (); + $this->assertSame (array (), $res); + } + + public function test_insert1 () + { + // Insert without value : raise an exception + $this->setExpectedException ("Exception"); + $db1 = $this->db1 (); + $res = $db1->insert()->execute (); + $db1->disconnect (); + } + + public function test_insert2 () + { + // Insert : missing not null field : exception + $this->setExpectedException ("Exception"); + $db1 = $this->db1 (); + $res = $db1->insert() + ->setValues(array ("group"=>"group1", "where"=>"where")) + ->execute (); + $db1->disconnect (); + } + + public function test_insert3 () + { + // Insert : first row inserted + $db1 = $this->db1 (); + $res = $db1->insert()->setValues(array ("group"=>"group1", "where"=>"where", + "object"=>"object"))->execute (); + $db1->disconnect (); + // As the key is not an autoincrement, the lastInsertID can be 0 or 1 + $this->assertGreaterThanOrEqual ($res, "0"); + } + + public function test_select2 () + { + // Select all on the table : nothing + $db1 = $this->db1 (); + $res = $db1->select()->execute (); + $db1->disconnect (); + $this->assertSame (array (array ("group"=>"group1", "object"=>"object", + "where"=>"where", "with space"=>null)), + $res); + } + + public function test_update1 () + { + // update the all the rows of the table (without WHERE) + $db1 = $this->db1 (); + $res = $db1->update()->setValues(array ("group"=>"group2", "where"=>"where", + "object"=>"object"))->execute (); + $db1->disconnect (); + $this->assertSame (1, $res); + } + + public function test_select3 () + { + // Select all on the table after update + $db1 = $this->db1 (); + $res = $db1->select()->execute (); + $db1->disconnect (); + $this->assertSame (array (array ("group"=>"group2", "object"=>"object", + "where"=>"where", "with space"=>null)), + $res); + } + + public function test_update2 () + { + // update the all the rows of the table (with inexisting WHERE) + $db1 = $this->db1 (); + $res = $db1->update() + ->setValues(array ("group"=>"group2", "where"=>"where", + "object"=>"object")) + ->whereAdd ("group", "=", "group1") + ->execute (); + $db1->disconnect (); + $this->assertSame (0, $res); + } + + public function test_update3 () + { + // update the all the rows of the table (with existing WHERE) + $db1 = $this->db1 (); + $res = $db1->update() + ->setValues(array ("group"=>"group1", "where"=>"where", + "object"=>"object")) + ->whereAdd ("group", "=", "group2") + ->execute (); + $db1->disconnect (); + $this->assertSame (1, $res); + } + + public function test_update4 () + { + // update the all the rows of the table : NOT NULL value not provided + // (already existing in the table) + $db1 = $this->db1 (); + $res = $db1->update() + ->setValues(array ("group"=>"group1")) + ->execute (); + $db1->disconnect (); + $this->assertSame (1, $res); + } + + public function test_delete1 () + { + // Delete : WHERE return nothing + $db1 = $this->db1 (); + $res = $db1->delete () + ->whereAdd ("group", "=", "group2") + ->execute (); + $db1->disconnect (); + $this->assertSame (0, $res); + } + + public function test_delete2 () + { + // Delete all + $db1 = $this->db1 (); + $res = $db1->delete () + ->execute (); + $db1->disconnect (); + $this->assertSame (1, $res); + } + + public function test_select4 () + { + // Select all on the table : nothing + $db1 = $this->db1 (); + $res = $db1->select()->execute (); + $db1->disconnect (); + $this->assertSame (array (), $res); + } + + public function test_insert5 () + { + // Insert : first row inserted for TABLE 2 tests + $db1 = $this->db1 (); + $res = $db1->insert()->setValues(array ("group"=>"group1", "where"=>"where", + "object"=>"object"))->execute (); + $db1->disconnect (); + // As the key is not an autoincrement, the lastInsertID can be 0 or 1 + $this->assertGreaterThanOrEqual ($res, "0"); + } + + /////////////////// + /// TABLE 2 /// + /////////////////// + public function test_insertAutoincrement1 () + { + // Test autoincrement + $db1 = $this->db1 (); + $db2 = $this->db2 (); + $db2->setForeignObj ($db1); + $res = $db2->insert()->setValues(array ("gecos"=>"name", + "password"=>"toto", + "group"=>"group1"))->execute (); + $db1->disconnect (); + $db2->disconnect (); + $this->assertSame ("1", $res); + } + + public function test_insertAutoincrement2 () + { + // Test autoincrement + $db1 = $this->db1 (); + $db2 = $this->db2 (); + $db2->setForeignObj ($db1); + $res = $db2->insert()->setValues(array ("gecos"=>"firstname2", + "password"=>"toto2", + "group"=>"group1"))->execute (); + $db1->disconnect (); + $db2->disconnect (); + $this->assertSame ("2", $res); + } + + public function test_insertAutoincrement3 () + { + // Test autoincrement + $db1 = $this->db1 (); + $db2 = $this->db2 (); + $db2->setForeignObj ($db1); + $res = $db2->insert()->setValues(array ("gecos"=>"firstname3", + "password"=>"toto3", + "group"=>"group1"))->execute (); + $db1->disconnect (); + $db2->disconnect (); + $this->assertSame ("3", $res); + } + + public function test_delete3 () + { + // Delete with WHERE clause + $db1 = $this->db1 (); + $db2 = $this->db2 (); + $db2->setForeignObj ($db1); + $res = $db2->delete () + ->whereAdd ("gecos", "LIKE", "firstname%") + ->execute (); + $db1->disconnect (); + $db2->disconnect (); + $this->assertSame (2, $res); + } + + public function test_select5 () + { + // Select all on the table : one entry "gecos"=>"name" + $db1 = $this->db1 (); + $db2 = $this->db2 (); + $db2->setForeignObj ($db1); + $res = $db2->select()->execute (); + $db1->disconnect (); + $db2->disconnect (); + $this->assertSame (array (array ("uid"=>1, + "gecos"=>"name", + "password"=>"toto", + "group"=>"group1")), $res); + } + + /// SCHEMA MANAGEMENT /// + public function test_getTableSchema1 () + { + $db3 = $this->db3 (); + $res = $db3->getTableSchema ("usersoo"); + $db3->disconnect (); + $this->assertSame ( + array ("fields"=>array ( + "uid"=>array ("integer", "not null", "autoincrement"), + "gecos"=>array ("varchar(255)", "not null"), + "password"=>array ("varchar(255)", "not null"), + "group" => array ("varchar(255)", "not null"), + ), + "primary"=>"uid", + "unique"=>array ("gecos","password"), + "foreign" => array ( + "group" => array ('groupedoo', 'group', 'ON DELETE CASCADE'), + ), + ), $res); + } +} diff --git a/Tests/ftsTest.php b/Tests/ftsTest.php new file mode 100644 index 0000000..855a115 --- /dev/null +++ b/Tests/ftsTest.php @@ -0,0 +1,174 @@ +search (""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array (), + "minuses"=>array ())); + } + + public function test_tokenizerSearch1 () + { + // Too small + $fts = new fts (); + $fts->search ("X"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array (), + "minuses"=>array ())); + } + + public function test_tokenizerSearch2 () + { + // One word + $fts = new fts (); + $fts->search ("XYZ"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ"), + "minuses"=>array (""))); + } + + public function test_tokenizerSearch3 () + { + // Two word + $fts = new fts (); + $fts->search ("XYZ 123"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ", "123"), + "minuses"=>array ("", ""))); + } + + public function test_tokenizerSearch4 () + { + // Three word + $fts = new fts (); + $fts->search ("XYZ 123 ABC"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ", "123", "ABC"), + "minuses"=>array ("", "", ""))); + } + + public function test_tokenizerSearch5 () + { + // Three word + $fts = new fts (); + $fts->search ("XYZ 123 ABC KLM"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ", "123", + "ABC", "KLM"), + "minuses"=>array ("", "", "", ""))); + } + + public function test_tokenizerSearch6 () + { + // Three word + $fts = new fts (); + $fts->search ("Louis-XYZ 123 -AéBCé KLM"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("Louis-XYZ", "123", + "AéBCé", "KLM"), + "minuses"=>array ("", "", "-", ""))); + } + + + public function test_tokenizerSentence0 () + { + // Empty sentence + $fts = new fts (); + $fts->search ("\"\""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array (), + "minuses"=>array ())); + } + + public function test_tokenizerSentence1 () + { + // One sentence only + $fts = new fts (); + $fts->search ("\"XYZ 123\""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ 123"), + "minuses"=>array (""))); + } + + public function test_tokenizerSentence2 () + { + // Two sentence + $fts = new fts (); + $fts->search ("\"XYZ 123\" \"ABC KLM\""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ 123", "ABC KLM"), + "minuses"=>array ("", ""))); + } + + public function test_tokenizerSentence3 () + { + // Three sentence + $fts = new fts (); + $fts->search ("\"XYZ 123\" -\"ABC KLM\" \"RPO YUI\""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ 123", "ABC KLM", + "RPO YUI"), + "minuses"=>array ("", "-", ""))); + } + + public function test_tokenizerMixed1 () + { + // One word and one sentence, starting by word + $fts = new fts (); + $fts->search ("XYZ \"ABC KLM\""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("XYZ", "ABC KLM"), + "minuses"=>array ("", ""))); + } + + public function test_tokenizerMixed2 () + { + // One word and one sentence, starting by sentence + $fts = new fts (); + $fts->search ("\"ABC KLM\" XYZ"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("ABC KLM", "XYZ"), + "minuses"=>array ("", ""))); + } + + public function test_tokenizerMixed3 () + { + // One word and two sentences, starting by sentence + $fts = new fts (); + $fts->search ("\"ABC KLM\" XYZ \"RPO YUI\""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("ABC KLM", "XYZ", + "RPO YUI"), + "minuses"=>array ("", "", ""))); + } + + public function test_tokenizerMixed4 () + { + // Two words and two sentences, starting by sentence + $fts = new fts (); + $fts->search ("\"ABC KLM\" XYZ \"RPO YUI\" 123"); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("ABC KLM", "XYZ", + "RPO YUI", "123"), + "minuses"=>array ("", "", "", ""))); + } + + public function test_tokenizerMixed5 () + { + // Two words and two sentences, starting by a word + $fts = new fts (); + $fts->search ("123 \"ABC KLM\" XYZ \"RPO YUI\""); + $res = $fts->getTokensMin (); + $this->assertSame ($res, array ("tokens"=>array ("123", "ABC KLM", + "XYZ", "RPO YUI"), + "minuses"=>array ("", "", "", ""))); + } +} diff --git a/dblayeroo.php b/dblayeroo.php new file mode 100644 index 0000000..cbe969b --- /dev/null +++ b/dblayeroo.php @@ -0,0 +1,2107 @@ + */ + +// dblayeroo.php + +/** Permit abstraction on the differents SQL databases available */ +class dblayeroo +{ + /** The table name to use + */ + private $table = null; + /** The tableprefix text to prepend to table name (Should finish by _) + * Just allow chars ! + */ + private $tableprefix = ""; + /** The fields with the definition of type, and special parameters + */ + private $fields = array (); + /** The primary field + */ + private $primary = null; + /** An array to define the unique fields (or array of unique fields) + */ + private $unique = null; + /** An array to define the foreign keys of the field + */ + private $foreign = array (); + /** Debug of the SQL + */ + private $debug = FALSE; + /** The connecting DSN + */ + private $dsn = null; + /** The driver to use + */ + private $driver = null; + /** The field group delimiter + */ + private $sep = ""; + /** Titles + */ + private $titles = array (); + + /** Limit to one instance of the connection to the same database + */ + // Based on an idea of http://tonylandis.com/php/php5-pdo-singleton-class/ + private static $instance = array (); + + /** 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) + { + $driver = @explode (":", $dsn); + if (! isset ($driver[0])) + $this->DBException (dgettext ("domframework", "No valid DSN provided")); + $driver[0] = strtolower ($driver[0]); + if (! in_array ($driver[0], pdo_drivers ())) + $this->DBException (sprintf (dgettext ("domframework", + "Driver PDO '%s' not available in PHP"), + $driver[0])); + $this->driver = $driver[0]; + // Force specifics initialisations + $this->dsn = $dsn; + switch ($driver[0]) + { + case "sqlite": + // Look at the right to write in database and in the directory + $file = substr ($dsn, 7); + if (! is_writeable (dirname ($file))) + $this->DBException (dgettext ("domframework", + "The directory for SQLite database is write protected")); + if (file_exists ($file) && ! is_writeable ($file)) + $this->DBException (dgettext ("domframework", + "The SQLite database file is write protected")); + if (function_exists ("posix_getuid") && + file_exists ($file) && + fileowner ($file) === posix_getuid ()) + chmod ($file, 0666); + // Print the instances of PDO objects stored : + // var_dump (self::$instance); + if (! array_key_exists ($this->dsn, self::$instance)) + { + $this->debugLog ("CONNECT TO SQLite DATABASE"); + try + { + self::$instance[$this->dsn] = new \PDO ($dsn, $username, $password, + $driver_options); + self::$instance[$this->dsn]->setAttribute (\PDO::ATTR_ERRMODE, + \PDO::ERRMODE_EXCEPTION); + } + catch (Exception $e) + { + $this->DBException ("PDO error : ".$e->getMessage ()); + } + } + + // Force ForeignKeys support (disabled by default) + self::$instance[$this->dsn]->exec ("PRAGMA foreign_keys = ON"); + $this->sep = "`"; + break; + case "mysql": + if (! array_key_exists ($this->dsn, self::$instance)) + { + $this->debugLog ("CONNECT TO MySQL DATABASE"); + try + { + $driver_options[\PDO::MYSQL_ATTR_FOUND_ROWS] = 1; + self::$instance[$this->dsn] = new \PDO ($dsn, $username, $password, + $driver_options); + self::$instance[$this->dsn]->setAttribute (\PDO::ATTR_ERRMODE, + \PDO::ERRMODE_EXCEPTION); + } + catch (Exception $e) + { + $this->DBException ("PDO error : ".$e->getMessage ()); + } + } + + // Set the coding to UTF8 + self::$instance[$this->dsn]->exec ("SET CHARACTER SET utf8"); + $this->sep = "`"; + break; + case "pgsql": + if (! array_key_exists ($this->dsn, self::$instance)) + { + $this->debugLog ("CONNECT TO PGSQL DATABASE"); + try + { + self::$instance[$this->dsn] = new \PDO ($dsn, $username, $password, + $driver_options); + self::$instance[$this->dsn]->setAttribute (\PDO::ATTR_ERRMODE, + \PDO::ERRMODE_EXCEPTION); + } + catch (Exception $e) + { + $this->DBException ("PDO error : ".$e->getMessage ()); + } + } + + // Set the coding to UTF8 + self::$instance[$this->dsn]->exec ("SET NAMES 'utf8'"); + $this->sep = "\""; + break; + default: + $this->DBException (dgettext ("domframework", + "Unknown PDO driver provided")); + } + return self::$instance[$this->dsn]; + } + + /** This function disconnect the database. It is normally only used in phpunit + * unit tests + */ + public function disconnect () + { + unset (self::$instance[$this->dsn]); + } + + /** Start a new Transaction + */ + public function beginTransaction () + { + return self::$instance[$this->dsn]->beginTransaction (); + } + + /** Commit (validate) a transaction + */ + public function commit () + { + return self::$instance[$this->dsn]->commit (); + } + + /** RollBack a transaction + */ + public function rollback () + { + return self::$instance[$this->dsn]->rollback (); + } + + /** Return the connected database name from DSN used to connect + */ + public function databasename () + { + if ($this->sep === "") + $this->DBException (dgettext ("domframework", "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->sep === "") + $this->DBException (dgettext ("domframework", "Database not connected")); + switch (self::$instance[$this->dsn]->getAttribute (\PDO::ATTR_DRIVER_NAME)) + { + case "sqlite": + $req = "SELECT name FROM sqlite_master WHERE type='table'"; + $st = self::$instance[$this->dsn]->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 = self::$instance[$this->dsn]->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 = self::$instance[$this->dsn]->prepare ($req); + $st->execute (); + $res = array (); + while ($d = $st->fetch (\PDO::FETCH_ASSOC)) + $res[] = $d["tablename"]; + break; + default: + $this->DBException (dgettext ("domframework", + "Unknown database driver in listTables")); + } + return $res; + } + + /** 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 () + { + $this->debugLog ("Entering createTable"); + if ($this->sep === "") + throw new Exception (dgettext("domframework", "Database not connected"), + 500); + if (count ($this->fields) === 0) + throw new Exception (dgettext("domframework", "No Field defined"), 500); + if ($this->table === null) + throw new \Exception (dgettext("domframework", + "No table name defined to create the table"), 500); + switch (self::$instance[$this->dsn]->getAttribute(\PDO::ATTR_DRIVER_NAME)) + { + case "sqlite": + $sql = "CREATE TABLE IF NOT EXISTS ". + "$this->sep$this->tableprefix$this->table$this->sep ". + "(\n"; + $i = 0; + foreach ($this->fields as $field=>$params) + { + if ($i > 0) + $sql .= ",\n"; + // Name of field + $sql .= "$this->sep$field$this->sep "; + switch ($this->fieldTypeLight ($field)) + { + case "integer": + $sql .= "INTEGER"; + $params = array_slice ($params, 1); + break; + case "varchar": + $length = $this->fieldLength ($field); + $sql .= "VARCHAR($length)"; + $params = array_slice ($params, 1); + 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 ( + dgettext("domframework", + "Unknown type '%s' provided for field '%s'"), + $this->fieldTypeLight ($field), $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 (sprintf (dgettext("domframework", + "Unknown additionnal parameter '%s' for field '%s'"), + $p, $field), 500); + } + } + $i ++; + } + // Unique fields + if ($this->unique !== null) + { + if (!is_array ($this->unique)) + throw new Exception (dgettext("domframework", + "The Unique field definition is not an array"), + 500); + foreach ($this->unique as $u) + { + $sql .= ",\n UNIQUE ($this->sep"; + if (is_array ($u)) + $sql .=implode ("$this->sep,$this->sep", $u); + else + $sql .= $u; + $sql .="$this->sep)"; + } + } + // Foreign keys + $i = 0; + foreach ($this->foreign as $field=>$k) + { + $sql .= ",\n FOREIGN KEY($this->sep$field$this->sep) ". + "REFERENCES $this->sep".$k[0]."$this->sep($this->sep". + $k[1]."$this->sep)"; + if (isset ($k[2])) + $sql .= " ".$k[2]; + $i++; + } + $sql .=")"; + break; + case "mysql": + $sql = "CREATE TABLE IF NOT EXISTS ". + "$this->sep$this->tableprefix$this->table$this->sep ". + "(\n"; + $i = 0; + foreach ($this->fields as $field=>$params) + { + if ($i > 0) + $sql .= ",\n"; + // Name of field + $sql .= "$this->sep$field$this->sep "; + switch ($this->fieldTypeLight ($field)) + { + case "integer": + $sql .= "INTEGER"; + $params = array_slice ($params, 1); + break; + case "varchar": + $length = $this->fieldLength ($field); + $sql .= "VARCHAR($length)"; + $params = array_slice ($params, 1); + 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 ( + dgettext("domframework", + "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 ( + dgettext("domframework", + "Unknown additionnal '%s' parameter for field '%s'"), + $p, $field), 500); + } + } + $i ++; + } + // Unique fields + if ($this->unique !== null) + { + foreach ($this->unique as $u) + { + $sql .= ",\n UNIQUE ($this->sep"; + if (is_array ($u)) + $sql .=implode ("$this->sep,$this->sep", $u); + else + $sql .= $u; + $sql .="$this->sep)"; + } + } + // Foreign keys + $i = 0; + foreach ($this->foreign as $field=>$k) + { + $sql .= ",\n FOREIGN KEY($this->sep$field$this->sep) ". + "REFERENCES $this->sep".$k[0]."$this->sep($this->sep". + $k[1]."$this->sep)"; + if (isset ($k[2])) + $sql .= " ".$k[2]; + if ($i > 0) + $sql .= ","; + $i++; + } + $sql .=") ENGINE=InnoDB DEFAULT CHARSET=utf8;"; + break; + case "pgsql": + $sql = "CREATE TABLE IF NOT EXISTS ". + "\"$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 + { + switch ($this->fieldTypeLight ($field)) + { + case "integer": + $sql .= "INTEGER"; + $params = array_slice ($params, 1); + break; + case "varchar": + $length = $this->fieldLength ($field); + $sql .= "VARCHAR($length)"; + $params = array_slice ($params, 1); + 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 ( + dgettext("domframework", + "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 ( + dgettext("domframework", + "Unknown additionnal parameter '%s' for field '%s'"), + $p, $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 (dgettext("domframework", + "PDO Engine not supported in dbLayeroo"), 500); + } + + $this->debugLog ($sql); + return self::$instance[$this->dsn]->exec ($sql); + } + + /** Drop the table + */ + public function dropTable () + { + $this->debugLog ("Entering dropTable ()"); + if ($this->sep === "") + throw new Exception (dgettext("domframework", "Database not connected")); + if ($this->table === null) + throw new \Exception (dgettext("domframework", + "No table name defined to drop the table"), 500); + $sql = "DROP TABLE $this->sep$this->tableprefix$this->table$this->sep"; + $this->debugLog ($sql); + return self::$instance[$this->dsn]->exec ($sql); + } + + /** Get the informations about a table + * @param string $tableName The table to examine + */ + public function getTableSchema ($tableName) + { + $this->debugLog ("Entering getTableSchema (",$tableName,")"); + switch (self::$instance[$this->dsn]->getAttribute(\PDO::ATTR_DRIVER_NAME)) + { + case "sqlite": + $st = self::$instance[$this->dsn]->prepare ( + "PRAGMA table_info($tableName)"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + $fields = array (); + $unique = array (); + $foreign = array (); + $primary = ""; + foreach ($content as $row) + { + $type = str_replace (" ", "", strtolower ($row["type"])); + $fields[$row["name"]][] = $type; + if ($row["notnull"] === "1") + $fields[$row["name"]][] = "not null"; + if ($row["pk"] === "1") + $primary = $row["name"]; + } + + $st = self::$instance[$this->dsn]->prepare ( + "PRAGMA index_list($tableName)"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + foreach ($content as $c) + { + $st = self::$instance[$this->dsn]->prepare ( + "PRAGMA index_info(".$c["name"].")"); + $st->execute (); + $content2 = $st->fetchAll (\PDO::FETCH_ASSOC); + if (count ($content2) > 1) + { + $index = array (); + foreach ($content2 as $c2) + { + $index[] = $c2["name"]; + } + $unique[$content2[0]["cid"]-1] = $index; + } + elseif (count ($content2) === 1) + { + $index = $content2[0]["name"]; + $unique[$content2[0]["cid"]-1] = $index; + } + } + ksort ($unique); + + $st = self::$instance[$this->dsn]->prepare ( + "SELECT * FROM sqlite_sequence WHERE name='$tableName'"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + if (count ($content) > 0 && $primary !== "") + $fields[$primary][] = "autoincrement"; + + $st = self::$instance[$this->dsn]->prepare ( + "PRAGMA foreign_key_list('$tableName')"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + foreach ($content as $for) + { + $tmp = array ($for["table"], $for["to"]); + $cascade = ""; + if ($for["on_update"] !== "NO ACTION") + $cascade .= "ON UPDATE ".$for["on_update"]; + if ($for["on_delete"] !== "NO ACTION") + $cascade .= "ON DELETE ".$for["on_delete"]; + if ($cascade !== "") + $tmp[] = $cascade; + $foreign[$for["from"]] = $tmp; + } + return array ("fields" => $fields, + "primary" => $primary, + "unique" => $unique, + "foreign" => $foreign); + break; + case "mysql": + $st = self::$instance[$this->dsn]->prepare ( + "SHOW COLUMNS FROM `$tableName`"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + $fields = array (); + $unique = array (); + $foreign = array ("TBD"); + $primary = ""; + foreach ($content as $col) + { + $tmp = array (); + if ($col["Type"] === "int(11)") + $tmp[] = "integer"; + else + $tmp[] = $col["Type"]; + if ($col["Null"] === "NO") + $tmp[] = "not null"; + if ($col["Extra"] === "auto_increment") + $tmp[] = "autoincrement"; + $fields[$col["Field"]] = $tmp; + } + $st = self::$instance[$this->dsn]->prepare ( + "SHOW INDEX FROM `$tableName`"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + foreach ($content as $col) + { + if ($col["Key_name"] === "PRIMARY") + $primary = $col["Column_name"]; + else + { + if ($col["Non_unique"] === "1") + continue; + if (array_key_exists ($col["Key_name"], $unique)) + { + if (!is_array ($unique[$col["Key_name"]])) + $unique[$col["Key_name"]] = array ($unique[$col["Key_name"]]); + $unique[$col["Key_name"]][] = $col["Column_name"]; + } + else + { + $unique[$col["Key_name"]] = $col["Column_name"]; + } + } + } + $unique = array_values ($unique); + $st = self::$instance[$this->dsn]->prepare (" + SELECT UPDATE_RULE,DELETE_RULE,COLUMN_NAME, + kColUsage.REFERENCED_TABLE_NAME,REFERENCED_COLUMN_NAME + FROM information_schema.REFERENTIAL_CONSTRAINTS AS rCons, + information_schema.KEY_COLUMN_USAGE as kColUsage + WHERE rCons.CONSTRAINT_SCHEMA=:dbname AND rCons.TABLE_NAME=:table + AND rCons.CONSTRAINT_NAME=kColUsage.CONSTRAINT_NAME"); + $st->execute (array(':dbname' => $this->databasename (), + ':table' => $tableName)); + $foreignTmp = $st->fetchAll (\PDO::FETCH_ASSOC); + $foreign = array (); + foreach ($foreignTmp as $f) + { + $tmp = array (); + $tmp[] = $f["REFERENCED_TABLE_NAME"]; + $tmp[] = $f["REFERENCED_COLUMN_NAME"]; + $tmp[2] = ""; + if ($f["UPDATE_RULE"] !== "NO ACTION" && + $f["UPDATE_RULE"] !== "RESTRICT") + $tmp[2] .= "ON UPDATE ".$f["UPDATE_RULE"]." "; + if ($f["DELETE_RULE"] !== "NO ACTION" && + $f["DELETE_RULE"] !== "RESTRICT") + $tmp[2] .= "ON DELETE ".$f["DELETE_RULE"]; + if ($tmp[2] !== "") + $tmp[2] = trim ($tmp[2]); + else + unset ($tmp[2]); + $foreign[$f["COLUMN_NAME"]] = $tmp; + } + return array ("fields" => $fields, + "primary" => $primary, + "unique" => $unique, + "foreign" => $foreign); + break; + case "pgsql": + $st = self::$instance[$this->dsn]->prepare ( + "SELECT * + FROM information_schema.columns + WHERE table_schema='public' and table_name='$tableName'"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + $fields = array (); + $unique = array (); + $foreign = array (); + $primary = ""; + foreach ($content as $col) + { + $tmp = array (); + if ($col["data_type"] === "character varying") + $tmp[] = "varchar(".$col["character_maximum_length"].")"; + else + $tmp[] = $col["data_type"]; + if ($col["is_nullable"] === "NO") + $tmp[] = "not null"; + if (substr ($col["column_default"], 0, 7) === "nextval") + { + $tmp[] = "autoincrement"; + $primary = $col["column_name"]; + } + $fields[$col["column_name"]] = $tmp; + } + + $st = self::$instance[$this->dsn]->prepare ( + "select * + from information_schema.constraint_column_usage + where table_name='$tableName'"); + $st->execute (); + $content = $st->fetchAll (\PDO::FETCH_ASSOC); + foreach ($content as $col) + { + if (array_key_exists ($col["constraint_name"], $unique)) + { + if (! is_array ($unique[$col["constraint_name"]])) + $unique[$col["constraint_name"]] = + array ($unique[$col["constraint_name"]]); + $unique[$col["constraint_name"]][] = $col["column_name"]; + } + else + { + $unique[$col["constraint_name"]] = $col["column_name"]; + } + } + $unique = array_values ($unique); + $st = self::$instance[$this->dsn]->prepare (" + SELECT kColUsage1.column_name COLUMN_NAME, + kColUsage2.table_name REFERENCED_TABLE_NAME, + kColUsage2.column_name REFERENCED_COLUMN_NAME, + update_rule,delete_rule + FROM information_schema.KEY_COLUMN_USAGE AS kColUsage1, + information_schema.KEY_COLUMN_USAGE AS kColUsage2, + information_schema.REFERENTIAL_CONSTRAINTS AS rCons + WHERE kColUsage1.table_catalog=:dbname AND kColUsage1.table_name=:table + AND rCons.constraint_name=kColUsage1.constraint_name + AND rCons.unique_constraint_name=kColUsage2.constraint_name + "); + $st->execute (array(':dbname' => $this->databasename (), + ':table' => $tableName)); + $foreignTmp = $st->fetchAll (\PDO::FETCH_ASSOC); + $foreign = array (); + foreach ($foreignTmp as $f) + { + $tmp = array (); + $tmp[] = $f["referenced_table_name"]; + $tmp[] = $f["referenced_column_name"]; + $tmp[2] = ""; + if ($f["update_rule"] !== "NO ACTION" && + $f["update_rule"] !== "RESTRICT") + $tmp[2] .= "ON UPDATE ".$f["update_rule"]." "; + if ($f["delete_rule"] !== "NO ACTION" && + $f["delete_rule"] !== "RESTRICT") + $tmp[2] .= "ON DELETE ".$f["delete_rule"]; + if ($tmp[2] !== "") + $tmp[2] = trim ($tmp[2]); + else + unset ($tmp[2]); + $foreign[$f["column_name"]] = $tmp; + } + + return array ("fields" => $fields, + "primary" => $primary, + "unique" => $unique, + "foreign" => $foreign); + break; + default: + throw new Exception (dgettext("domframework", + "PDO Engine not supported in dbLayeroo"), 500); + } + } + + /** Return the type of the provided field + * @param string $field The field to get the type + */ + private function fieldTypeComplete ($field) + { +// $this->debugLog ("Entering fieldTypeComplete (",$field,")"); + if (! array_key_exists ($field, $this->fields)) + $this->DBException (sprintf ( + "fieldType : can't find the definition for field '%s'", + $field)); + if (! array_key_exists (0, $this->fields[$field])) + $this->DBException (sprintf ( + "fieldType : can't find the type for field '%s'", + $field)); + if (! is_string ($this->fields[$field][0])) + $this->DBException (sprintf ( + "fieldType : The type of field '%s' is not a string", + $field)); + $type = strtolower ($this->fields[$field][0]); + $type = str_replace (" ", "", $type); + return $type; + } + + /** Return the type of the provided field. For varchar(255), return only + * varchar + * @param string $field The field to get the type + */ + private function fieldTypeLight ($field) + { + $type = $this->fieldTypeComplete ($field); + list ($type, ) = explode ("(", $type); + return $type; + } + + /** Return the length of a field (generally a varchar) + * @param string $field The field to get the type + */ + private function fieldLength ($field) + { + $type = $this->fieldTypeComplete ($field); + $pos = strpos ($type, "("); + if ($pos === false) + $this->DBException (sprintf ( + "fieldLength : no length defined for field '%s'", $field)); + $length = intval (substr ($type, 1+$pos, -1)); + if ($length === 0) + $this->DBException (sprintf ( + "fieldLength : Length equal to Zero for field '%s'", $field)); + return $length; + } + + ///////////////////////////// + /// GETTERS / SETTERS /// + ///////////////////////////// + /** Get/Set the table property + * @param string|null $table The table to use + */ + public function table ($table=null) + { + $this->debugLog ("Entering table (",$table,")"); + if ($table === null) + return $this->table; + if (! is_string ($table)) + $this->DBException ("Parameter table invalid: not a string"); + if (mb_strlen ($table) > 63) + $this->DBException ("Parameter table invalid: too long"); + $this->table = $table; + return $this; + } + + /** Get/Set the tableprefix property + * @param string|null $tableprefix The prefix to append + */ + public function tableprefix ($tableprefix=null) + { + $this->debugLog ("Entering tableprefix (",$tableprefix,")"); + if ($tableprefix === null) + return $this->tableprefix; + if (! is_string ($tableprefix)) + $this->DBException ("Parameter tableprefix invalid: not a string"); + // 64 - at least one char for the table name + if (mb_strlen ($tableprefix) > 63) + $this->DBException ("Parameter tableprefix invalid: too long"); + $this->tableprefix = $tableprefix; + return $this; + } + + /** Get/Set the fields property + * The fields to define are in the format: + * array ("fieldName"=>array ("type"[, "not null"[, "autoincrement"]])) + * @param array|null $fields The fields to define + */ + public function fields ($fields=null) + { + $this->debugLog ("Entering fields (VALUE)"); + if ($fields === null) + return $this->fields; + if (! is_array ($fields)) + $this->DBException ("Parameter fields invalid: not an array"); + foreach ($fields as $field=>$params) + { + if (mb_strlen ($field) > 64) + $this->DBException ("Parameter fields invalid: column name too long"); + if (! is_array ($params)) + $this->DBException ("Parameter fields invalid: ". + "param not an array for '$field'"); + if (! array_key_exists (0, $params)) + $this->DBException ("Parameter fields invalid: ". + "No type of column provided for '$field'"); + if (preg_match ("#^(data|datetime|integer|time|varchar\(\d+\))$#i", + $params[0]) !== 1) + $this->DBException ("Parameter fields invalid: ". + "Unknown column type provided for '$field'"); + if (array_key_exists (1, $params) && + $params[1] !== "not null" && $params[1] !== "autoincrement") + $this->DBException ("Parameter fields invalid: ". + "Second parameter invalid for '$field'"); + if (array_key_exists (2, $params) && + $params[2] !== "autoincrement") + $this->DBException ("Parameter fields invalid: ". + "Third parameter invalid for '$field'"); + } + $this->fields = $fields; + return $this; + } + + /** Get/Set the primary property + * @param string|null $primary The primary key to use + */ + public function primary ($primary=null) + { + $this->debugLog ("Entering primary (",$primary,")"); + if ($primary === null) + return $this->primary; + if (! is_string ($primary)) + $this->DBException ("Parameter primary invalid: not a string"); + if (mb_strlen ($primary) > 64) + $this->DBException ("Parameter primary invalid: too long"); + if (! array_key_exists ($primary, $this->fields)) + $this->DBException ("Parameter primary invalid: column doesn't exists"); + $this->primary = $primary; + return $this; + } + + /** Get/Set the unique property + * @param array|null $unique The unique fields constraint to add + */ + public function unique ($unique=null) + { + $this->debugLog ("Entering unique (VALUE)"); + if ($unique === null) + return $this->unique; + if (! is_array ($unique)) + $this->DBException ("Parameter unique invalid: not an array"); + foreach ($unique as $u1) + { + if (is_string ($u1)) + { + if (mb_strlen ($u1) > 64) + $this->DBException ("Parameter unique invalid: too long '$u1'"); + } + elseif (is_array ($u1)) + { + foreach ($u1 as $u2) + { + if (is_string ($u2)) + { + if (mb_strlen ($u2) > 64) + $this->DBException ("Parameter unique invalid: too long '$u2'"); + } + else + $this->DBException ("Parameter unique invalid: Not string ". + "in array"); + } + } + else + $this->DBException ("Parameter unique invalid: Not string nor array: ". + gettype ($u1)); + } + $this->unique = $unique; + return $this; + } + + /** Get/Set the foreign property + * @param array|null $foreign The definition of the foreign constraint + */ + public function foreign ($foreign=null) + { + $this->debugLog ("Entering foreign (VALUE)"); + if ($foreign === null) + return $this->foreign; + if (! is_array ($foreign)) + $this->DBException ("Parameter foreign invalid: not an array"); + foreach ($foreign as $col=>$params) + { + if (! array_key_exists ($col, $this->fields)) + $this->DBException ("Parameter foreign invalid: column doesn't exists"); + if (! is_array ($params)) + $this->DBException ("Parameter foreign invalid: ". + "parameters not in array"); + if (! array_key_exists (0, $params)) + $this->DBException ("Parameter foreign invalid: ". + "parameter 0 doesn't exists"); + if (! array_key_exists (1, $params)) + $this->DBException ("Parameter foreign invalid: ". + "parameter 1 doesn't exists"); + if (! is_string ($params[0])) + $this->DBException ("Parameter foreign invalid: ". + "parameter 0 is not a string"); + if (! is_string ($params[1])) + $this->DBException ("Parameter foreign invalid: ". + "parameter 1 is not a string"); + if (mb_strlen ($params[0] > 64)) + $this->DBException ("Parameter foreign invalid: ". + "parameter 0 is too long"); + if (mb_strlen ($params[1] > 64)) + $this->DBException ("Parameter foreign invalid: ". + "parameter 1 is too long"); + if (array_key_exists (2, $params)) + { + preg_match_all ("#^(ON UPDATE ". + "(CASCADE|RESTRICT|NO ACTION|SET DEFAULT|SET NULL) ?)?". + "(ON DELETE ". + "(CASCADE|RESTRICT|NO ACTION|SET DEFAULT|SET NULL))?$#", + $params[2], $matches); + if ($matches[1] === "" && $matches[3] === "") + $this->DBException ("Parameter foreign invalid: ". + "Unknown action provided"); + } + } + $this->foreign = $foreign; + return $this; + } + + /** Get/Set the debug property + * @param integer|null $debug Set the debug value + */ + public function debug ($debug=null) + { + $this->debugLog ("Entering debug (",$debug,")"); + if ($debug === null) + return $this->debug; + if (! is_int ($debug)) + $this->DBException ("Parameter debug invalid: not an integer"); + $this->debug = $debug; + return $this; + } + + /** Get/Set the dsn property + * @param string|null $dsn Set the DSN property of PDO + */ + public function dsn ($dsn=null) + { + $this->debugLog ("Entering dsn (",$dsn,")"); + if ($dsn === null) + return $this->dsn; + if (! is_string ($dsn)) + $this->DBException ("Parameter dsn invalid : not a string"); + $this->dsn = $dsn; + return $this; + } + + /** Get/Set the titles property + * @param array|null $titles The titles of the fields + */ + public function titles ($titles=null) + { + $this->debugLog ("Entering titles (VALUE)"); + if ($titles === null) + return $this->titles; + if (! is_array ($titles)) + $this->DBException ("Parameter titles invalid: not an array"); + foreach ($titles as $title=>$translation) + { + if (! is_string ($title)) + $this->DBException ("Parameter titles invalid: title not a string"); + if (mb_strlen ($title) > 64) + $this->DBException ("Parameter titles invalid: title too long"); + if (! is_string ($translation)) + $this->DBException ("Parameter titles invalid: ". + "translation not a string"); + if (mb_strlen ($translation) > 64) + $this->DBException ("Parameter titles invalid: translation too long"); + } + $this->titles = $titles; + return $this; + } + + ///////////////////////////////////// + /// MANAGE THE REQUEST BY OOP /// + ///////////////////////////////////// + /** The command to use + */ + private $command = ""; + /** The DISTINCT option + */ + private $distinct = ""; + /** The columns to display in SELECT, with the tables names and the separators + * correctely defined + */ + private $displayColumn = array (); + /** Manage the joins + */ + private $joins = array (); + /** The WHERE expression + */ + private $whereExpression = array (); + /** The values for each parameter for the WHERE condition + */ + private $whereValues = array (); + /** The ORDER expression + */ + private $orderExpression = array (); + /** The LIMIT expression + */ + private $limitExpression = ""; + /** The values to SET in INSERT/UPDATE + */ + private $setValues = array (); + /** The types to SET in INSERT/UPDATE + */ + private $setType = array (); + /** The dblayeroo object of the foreign keys tables to check + */ + private $setForeignObj = array (); + + /** The debug depth (as we clone object, the depth is increased to debug + * easily the functions + */ + private $debugDepth = 1; + + /** Reinit the SQL request + */ + public function clearRequest () + { + $this->debugLog ("Entering clearRequest ()"); + $this->command = ""; + $this->distinct = ""; + $this->displayColumn = array (); + $this->joins = array (); + $this->whereExpression = array (); + $this->whereValues = array (); + $this->orderExpression = array (); + $this->limitExpression = ""; + $this->setValues = array (); + $this->setType = array (); + $this->setForeignObj = array (); + } + + /** Define a new foreign object + * @param object $object The dblayeroo object to use for foreign constraint + * checks + */ + public function setForeignObj ($object) + { + $this->debugLog ("Entering setForeignObj (OBJECT)"); + if (! is_object ($object)) + $this->DBException ("Invalid setForeignObj parameter: not an object"); + if (get_class ($object) !== __CLASS__) + $this->DBException ( + "Invalid object provided to setForeignObj (not dblayeroo object)"); + if (! isset ($object->table)) + $this->DBException ( + "Invalid object provided to setForeignObj (no table defined)"); + $this->setForeignObj[$object->tableprefix.$object->table] = $object; + } + + /** Define the command to execute. Can be + * "SELECT", "INSERT", "DELETE", "UPDATE". + * @param string $command The command to execute + */ + public function command ($command) + { + $this->debugLog ("Entering command (",$command,")"); + $allowed = array ("SELECT", "INSERT", "DELETE", "UPDATE"); + if (! is_string ($command)) + $this->DBException ("Invalid command provided (not string)"); + $command = strtoupper ($command); + if (! in_array ($command, $allowed)) + $this->DBException ("Invalid command provided (unknown command)"); + $this->command = $command; + return $this; + } + + /** Alias of command ("SELECT") + */ + public function select () + { + $this->command = "SELECT"; + return $this; + } + + /** Alias of command ("INSERT") + */ + public function insert () + { + $this->command = "INSERT"; + return $this; + } + + /** Alias of command ("DELETE") + */ + public function delete () + { + $this->command = "DELETE"; + return $this; + } + + /** Alias of command ("UPDATE") + */ + public function update () + { + $this->command = "UPDATE"; + return $this; + } + + /** Set the DISTINCT option + */ + public function setDistinct () + { + $this->distinct = "DISTINCT"; + return $this; + } + + /** Set the columns to display for the next SELECT request + * @param array|string $columnNames The columns name, separated by comma + * By default, display all the columns + */ + public function displayColumn ($columnNames) + { + $this->debugLog ("Entering displayColumn (",$columnNames,")"); + if (! is_string ($columnNames) && ! is_array ($columnNames)) + $this->DBException ( + "Invalid columnNames provided (not string and not array)"); + if (is_string ($columnNames)) + $columnNames = explode (",", $columnNames); + foreach ($columnNames as $name) + { + if (! array_key_exists ($name, $this->fields)) + $this->DBException (sprintf ( + "Invalid field to display '%s' : not defined in table", $name)); + $this->displayColumn[] = $this->sep.$this->tableprefix.$this->table. + $this->sep.".". + $this->sep.$name.$this->sep; + } + return $this; + } + + /** Do a inner join between two dblayer objects + * The join array is a associated array with local field as key and distant + * field as value + * @param object $object The dblayeroo object to use for searching the join + * data + * @param array $joinArray The values to search for join + */ + public function joinInner ($object, $joinArray) + { + $this->debugLog ("Entering joinInner (OBJECT, JOINARRAY)"); + return $this->joinReal ("INNER", $object, $joinArray); + } + + /** Do a left join between two dblayer objects + * The join array is a associated array with local field as key and distant + * field as value + * @param object $object The dblayeroo object to use for searching the join + * data + * @param array $joinArray The values to search for join + */ + public function joinLeft ($object, $joinArray) + { + $this->debugLog ("Entering joinLeft (OBJECT, JOINARRAY)"); + return $this->joinReal ("LEFT", $object, $joinArray); + } + + /** Do a right join between two dblayer objects + * The join array is a associated array with local field as key and distant + * field as value + * @param object $object The dblayeroo object to use for searching the join + * data + * @param array $joinArray The values to search for join + */ + public function joinRight ($object, $joinArray) + { + $this->debugLog ("Entering joinRight (OBJECT, JOINARRAY)"); + return $this->joinReal ("RIGHT", $object, $joinArray); + } + + /** Do the real join + * @param string $joinType The join type to use ("INNER", "LEFT", "RIGHT") + * @param object $object The dblayeroo object to use for searching the join + * data + * @param array $joinArray The values to search for join + */ + private function joinReal ($joinType, $object, $joinArray) + { + $this->debugLog ("Entering joinReal (",$joinType,", OBJECT, JOINARRAY)"); + if (! is_string ($joinType)) + $this->DBException ("Invalid joinType provided to join (not string)"); + if (! in_array ($joinType, array ("INNER", "LEFT", "RIGHT"))) + $this->DBException ("Invalid joinType provided to join (not known)"); + if (! is_object ($object)) + $this->DBException ("Invalid object provided to join (not object)"); + if (get_class ($object) !== __CLASS__) + $this->DBException ( + "Invalid object provided to join (not dblayeroo object)"); + if ($this->dsn !== $object->dsn) + $this->DBException ( + "DSN different : don't support JOIN between databases"); + + if (! is_array ($joinArray)) + $this->DBException ("Invalid joinArray provided (not array)"); + if (empty ($joinArray)) + $this->DBException ("Invalid joinArray provided (empty array)"); + foreach ($joinArray as $fieldLocal=>$fieldToJoin) + { + if (! array_key_exists ($fieldLocal, $this->fields)) + $this->DBException (sprintf ( + "Invalid field to join '%s' : not defined in Local table", + $fieldLocal)); + if (! array_key_exists ($fieldToJoin, $object->fields)) + $this->DBException (sprintf ( + "Invalid field to join '%s' : not defined in Distant table", + $fieldToJoin)); + } + if (! isset ($object->table) || $object->table === null || + trim ($object->table) === "") + $this->DBException ("No table defined in the Join object"); + if (! isset ($this->table) || $this->table === null || + trim ($this->table) === "") + $this->DBException ("No table defined in the local object"); + if (! isset ($object->tableprefix) || $object->tableprefix === null) + $this->DBException ("No tableprefix defined in the Join object"); + $tmp = ""; + foreach ($joinArray as $fieldLocal=>$fieldToJoin) + { + if ($tmp !== "") + $tmp .= " AND "; + $tmp .= + $this->sep.$this->tableprefix.$this->table.$this->sep.".". + $this->sep.$fieldLocal.$this->sep. + "=". + $this->sep.$object->tableprefix.$object->table.$this->sep.".". + $this->sep.$fieldToJoin.$this->sep; + } + // Correct the displayQuery in the main display fields with the display + // fields of object + $this->joins[] = "$joinType JOIN ". + $this->sep.$object->tableprefix.$object->table.$this->sep." ON $tmp"; + foreach ($object->displayColumn as $col) + { + array_unshift ($this->displayColumn, $col); + } + // Correct the WHERE in the main with the object WHERE + $this->whereExpression = array_merge ($object->whereExpression, + $this->whereExpression); + $this->whereValues = array_merge ($object->whereValues, $this->whereValues); + return $this; + } + + /** Set a new WHERE expression value + * @param string $field The field to check + * @param string $operator The operator ("=", "<=", ">=", "!=", "NOT LIKE", + * "LIKE", "IS NULL", "REGEXP", "NOT REGEXP") + * @param string|null $value The value to search ("" if not provided) + */ + public function whereAdd ($field, $operator, $value = "") + { + $this->debugLog ("Entering whereAdd (",$field,", ",$operator,", ",$value, + ")"); + if (! is_string ($field)) + $this->DBException ("Invalid field provided (not string)"); + if (! is_string ($operator)) + $this->DBException ("Invalid operator provided (not string)"); + if (! is_string ($value) && ! is_null ($value) && ! is_integer ($value)) + $this->DBException ("Invalid value provided (not string nor null ". + "nor integer)"); + if (! array_key_exists ($field, $this->fields)) + $this->DBException (sprintf ( + "Invalid field to whereAdd '%s' : not defined in table", $field)); + $operator = strtoupper ($operator); + $allowed = array ("=", "<=", ">=", "!=", "LIKE", "NOT LIKE", "IS NULL", + "REGEXP", "NOT REGEXP"); + if (! in_array ($operator, $allowed)) + $this->DBException ("Invalid operator provided (unknown operator)"); + // TODO : Check if the value is corresponding to the type of the column + if (count ($this->whereExpression) && + end ($this->whereExpression) !== "AND" && + end ($this->whereExpression) !== "OR" && + end ($this->whereExpression) !== "(") + $this->whereExpression[] = "AND"; + if ($this->driver === "pgsql" && $operator === "REGEXP") + $operator = "~"; + if ($this->driver === "pgsql" && $operator === "NOT REGEXP") + $operator = "!~"; + $hash = md5 ("$field, $operator, $value"); + $this->whereExpression[] = + $this->sep.$this->tableprefix.$this->table.$this->sep.".". + $this->sep.$field.$this->sep." ".$operator." :$hash"; + $this->whereValues[$hash] = array ( + "field"=>$field, + "fieldfull"=> $this->tableprefix.$this->table.".".$field, + "operator"=>$operator, + "value"=>$value, + "hash"=>$hash, + "type"=>$this->fieldTypeLight ($field)); + return $this; + } + + /** Add a new AND to the WHERE expression + */ + public function whereAddAND () + { + $this->debugLog ("Entering whereAddAND ()"); + if (count ($this->whereExpression) === 0) + $this->DBException ("Can not add AND as there is no previous expression"); + $this->whereExpression[] = "AND"; + return $this; + } + + /** Add a new OR to the WHERE expression + */ + public function whereAddOR () + { + $this->debugLog ("Entering whereAddOR ()"); + if (count ($this->whereExpression) === 0) + $this->DBException ("Can not add OR as there is no previous expression"); + $this->whereExpression[] = "OR"; + return $this; + } + + /** Add a new Open Parenthesis to the WHERE expression + */ + public function whereAddParenthesisOpen () + { + $this->debugLog ("Entering whereAddParenthesisOpen ()"); + $this->whereExpression[] = "("; + return $this; + } + + /** Add a new Close Parenthesis to the WHERE expression + */ + public function whereAddParenthesisClose () + { + $this->debugLog ("Entering whereAddParenthesisClose ()"); + $this->whereExpression[] = ")"; + return $this; + } + + /** Add a new ORDER sort + * @param string $field The field to sort + * @param string|null $sort The sort order ("ASC", "DESC"); + */ + public function orderAdd ($field, $sort = "ASC") + { + $this->debugLog ("Entering orderAdd (",$field,", ",$sort,")"); + if (! is_string ($field)) + $this->DBException ("Invalid field provided (not string)"); + if (! is_string ($sort)) + $this->DBException ("Invalid sort provided (not string)"); + $sort = strtoupper ($sort); + if (! in_array ($sort, array ("ASC", "DESC"))) + $this->DBException ("Invalid sort provided (not ASC nor DESC)"); + if (! array_key_exists ($field, $this->fields)) + $this->DBException (sprintf ( + "Invalid field to orderAdd '%s' : not defined in table", $field)); + $this->orderExpression[] = $this->sep.$field.$this->sep." ".$sort; + return $this; + } + + /** Define a LIMIT for the request. + * To use only the nbLines, put a 0 on startLine + * @param integer $startLine The starting line in the result list + * @param integer $nbLines The number of lines to return + */ + public function limit ($startLine, $nbLines) + { + $this->debugLog ("Entering limit (",$startLine,", ",$nbLines,")"); + if (! preg_match ("/^\d+$/", $startLine)) + $this->DBException (sprintf ( + "Invalid startLine to limit '%d': not numerical", $startLine)); + if (! preg_match ("/^\d+$/", $nbLines)) + $this->DBException (sprintf ( + "Invalid nbLines to limit '%d': not numerical", $nbLines)); + $startLine = intval ($startLine); + $nbLines = intval ($nbLines); + if ($startLine !== 0) + $this->limitExpression = "$startLine,$nbLines"; + else + $this->limitExpression = "$nbLines"; + return $this; + } + + /** Define a LIMIT for the request. + * @param integer $nbLines The number of lines to return + */ + public function limitLines ($nbLines) + { + $this->debugLog ("Entering limitLines (",$nbLines,")"); + if (! preg_match ("/^\d+$/", $nbLines)) + $this->DBException (sprintf ( + "Invalid nbLines to limit '%d': not numerical", $nbLines)); + $nbLines = intval ($nbLines); + $this->limitExpression = "$nbLines"; + return $this; + } + + /** Set INSERT/UPDATE values + * - If the provided array is a associative array, the field name must be + * provided as key and the value as value. Each field=>val will be updated + * - It the provided array is a numeric array, it must be 2 long. The first + * is the field name, and the second the value + * @param array $values The values to INSERT or UPDATE + */ + public function setValues ($values) + { + $this->debugLog ("Entering setValues (",$values,")"); + if (! is_array ($values)) + $this->DBException ("Invalid values to setValues : not an array"); + $associative = null; + $tmpValues = array (); + $tmpType = array (); + $tmpField = array (); + foreach ($values as $key=>$val) + { + if ($associative === null) + { + if ($key === 0) + $associative = false; + elseif (is_string ($key) && strlen (trim ($key)) !== 0) + $associative = true; + } + elseif ($associative === false && + is_string ($key) && strlen (trim ($key)) !== 0) + $this->DBException ("Invalid values to setValues : mixed array"); + elseif ($associative === true && is_int ($key)) + $this->DBException ("Invalid values to setValues : mixed array"); + + if ($associative === true) + { + if (! array_key_exists ($key, $this->fields)) + $this->DBException (sprintf ( + "Invalid field to setValues '%s' : not defined in table", $key)); + $tmpValues[$key] = $val; + $tmpField[md5 ("$key, $val")] = $key; + $tmpType[md5 ("$key, $val")] = $this->fieldTypeLight ($key); + $this->debugLog ("setValues : Type for $key = ". + $this->fieldTypeLight ($key)); + } + else + { + $values = array_values ($values); + $tmpValues[$values[0]] = $values[1]; + } + } + $this->setValues = $tmpValues; + $this->setType = $tmpType; + return $this; + } + + /** Create the SQL request + */ + private function createRequest () + { + if ($this->sep === "") + $this->DBException (dgettext ("domframework", "Database not connected")); + if ($this->table === null) + $this->DBException (dgettext ("domframework", + "No table name defined to insert in the table")); + if ($this->unique === null) + $this->DBException (dgettext ("domframework", + "Unique fields of table are not defined")); + if (! is_array ($this->unique)) + $this->DBException (dgettext ("domframework", + "The unique configuration is not an array")); + switch ($this->command) + { + case "SELECT": + $sql = "SELECT"; + if ($this->distinct !== "") + $sql .= " ".$this->distinct; + $displayColumns = implode (",", $this->displayColumn); + if ($displayColumns === "") + $displayColumns = "*"; + $sql .= " $displayColumns FROM $this->sep$this->tableprefix". + "$this->table$this->sep"; + if (! empty ($this->joins)) + $sql .= " ". implode (" ", $this->joins); + if (! empty ($this->whereExpression)) + $sql .= " WHERE ". implode (" ", $this->whereExpression); + if (! empty ($this->orderExpression)) + $sql .= " ORDER BY ". implode (",", $this->orderExpression); + if (! empty ($this->limitExpression)) + $sql .= " LIMIT $this->limitExpression"; + // No set Values for SELECT + $this->setValues = array (); + break; + case "INSERT": + $sql = "INSERT INTO $this->sep$this->tableprefix$this->table$this->sep ("; + if (empty ($this->setValues)) + $this->DBException ("No values set to add in INSERT"); + $i = 0; + foreach ($this->setValues as $key=>$val) + { + if ($i > 0) + $sql .= ","; + $sql .= $this->sep.$key.$this->sep; + $i++; + } + $sql .= ") VALUES ("; + $i = 0; + foreach ($this->setValues as $key=>$val) + { + if ($i > 0) + $sql .= ","; + $sql .= ":".md5 ("$key, $val"); + $i++; + } + $sql .= ")"; + // No WHERE in INSERT : remove the WHERE parameters + $this->whereExpression = array (); + $this->whereValues = array (); + break; + case "DELETE": + $sql = "DELETE FROM $this->sep$this->tableprefix$this->table$this->sep"; + if (! empty ($this->whereExpression)) + $sql .= " WHERE ". implode (" ", $this->whereExpression); + if (! empty ($this->orderExpression)) + $sql .= " ORDER BY ". implode (",", $this->orderExpression); + if (! empty ($this->limitExpression)) + $sql .= " LIMIT $this->limitExpression"; + // No set Values for DELETE + $this->setValues = array (); + break; + case "UPDATE": + $sql = "UPDATE $this->sep$this->tableprefix$this->table$this->sep"; + if (empty ($this->setValues)) + $this-> DBException ("No values to set in UPDATE"); + $sql .= " SET "; + $i = 0; + foreach ($this->setValues as $key=>$val) + { + if ($i > 0) + $sql .= ","; + $hash = md5 ("$key, $val"); + $sql .= $this->sep.$key.$this->sep."=:".$hash; + $i++; + } + if (! empty ($this->whereExpression)) + $sql .= " WHERE ". implode (" ", $this->whereExpression); + if (! empty ($this->orderExpression)) + $sql .= " ORDER BY ". implode (",", $this->orderExpression); + if (! empty ($this->limitExpression)) + $sql .= " LIMIT $this->limitExpression"; + break; + default: + $this->DBException ("No command specified"); + } + return $sql; + } + + /** Prepare the request with the associated entries. + * If textForm is true, return a string to display what will be done + * If textForm is false, return a statement + * @param string $sql The SQL request to prepare + * @param boolean $textForm If true, return the result. If false prepare + * really the request + */ + private function prepareRequest ($sql, $textForm) + { + $text = ""; + if (!$textForm) + $st = self::$instance[$this->dsn]->prepare ($sql); + foreach ($this->whereValues as $hash=>$val) + { + $field = $val["field"]; + $value = $val["value"]; + $type = $val["type"]; + $text .= "DEBUG BIND WHERE : $hash ($field)->$value "; + if ($value === null) $text .= "NULL (null)\n"; + elseif ($type === "integer") $text .= "(integer)\n"; + elseif ($type === "varchar") $text .= "(varchar)\n"; + elseif ($type === "datetime") $text .= "(datetime)\n"; + elseif ($type === "date") $text .= "(date)\n"; + else + { + $text .= "(UNKNOWN)\n"; + $this->DBException ("TO BE DEVELOPPED : type=".$type); + } + if (!$textForm) + { + if ($value === null) + $st->bindValue (":$hash", $value, \PDO::PARAM_NULL); + elseif ($type === "integer") + $st->bindValue (":$hash", $value, \PDO::PARAM_INT); + elseif ($type === "varchar") + $st->bindValue (":$hash", "$value", \PDO::PARAM_STR); + elseif ($type === "datetime") + $st->bindValue (":$hash", $value, \PDO::PARAM_STR); + elseif ($type === "date") + $st->bindValue (":$hash", $value, \PDO::PARAM_STR); + else + $this->DBException ("prepareRequest:whereValues TO BE DEVELOPPED : ". + "type=$type"); + } + } + foreach ($this->setValues as $field=>$value) + { + $hash = md5 ("$field, $value"); + if (! array_key_exists ($hash, $this->setType)) + $this->DBException (sprintf ("Field '%s' not found in Type list", + $field)); + $type = $this->setType[$hash]; + $text .= "DEBUG BIND SET : $hash ($field)->$value "; + if ($value === null) $text .= "NULL (null)\n"; + elseif ($type === "integer") $text .= "(integer)\n"; + elseif ($type === "varchar") $text .= "(varchar)\n"; + elseif ($type === "datetime") $text .= "(datetime)\n"; + elseif ($type === "date") $text .= "(date)\n"; + else + { + $text .= "(UNKNOWN)\n"; + $this->DBException ("TO BE DEVELOPPED : ".$fields[$field][0]); + } + if (!$textForm) + { + if ($value === null) + $st->bindValue (":$hash", $value, \PDO::PARAM_NULL); + elseif ($this->setType[$hash] === "integer") + $st->bindValue (":$hash", $value, \PDO::PARAM_INT); + elseif ($this->setType[$hash] === "varchar") + $st->bindValue (":$hash", "$value", \PDO::PARAM_STR); + elseif ($this->setType[$hash] === "datetime") + $st->bindValue (":$hash", $value, \PDO::PARAM_STR); + elseif ($this->setType[$hash] === "date") + $st->bindValue (":$hash", $value, \PDO::PARAM_STR); + else + $this->DBException ("prepareRequest:setValues TO BE DEVELOPPED : ". + $this->fields[$field][0]); + } + } + if ($textForm) + return $text; + else + return $st; + } + + /** Return the query that will be executed + */ + public function getDisplayQuery () + { + $text = ""; + $sql = $this->createRequest (); + $text .= "$sql"; + $prep = $this->prepareRequest ($sql, true); + if ($prep !== "") + $text .= "\n$prep"; + return $text; + } + + /** Check the provided values which will be inserted or updated against the + * database structure. + * In update, do not forget to define the whereAdd parameters ! + * @param array $values The values to test + * @param boolean|null $update if true UPDATE request, else INSERT request + * @return array The errors found by field + */ + public function verify ($values, $update = false) + { + $update = !! $update; + $errors = array (); + if ($update === false) + { + // INSERT mode + if (! array_key_exists ($this->primary, $values)) + $values[$this->primary] = null; + // - Look if all the NOT NULL fields are filled + foreach ($this->fields as $field=>$params) + { + if (in_array ("not null", $params) && + ! array_key_exists ($field, $values)) + $errors[$field] = sprintf (dgettext ("domframework", + "Mandatory field '%s' not provided"), + $field); + elseif (! in_array ("not null", $params) && + ! array_key_exists ($field, $values)) + continue; + } + } + else + { + // UPDATE mode + } + + // INSERT or UPDATE mode + // - Check the validity of the content of the fields. Should be already done + // by the application, so just throw an Exception if the error is raised + foreach ($this->fields as $field=>$params) + { + $this->debugLog (" verify the field validity [$field]"); + if ($update !== false && ! array_key_exists ($field, $values)) + // In case of UPDATE, the values are already stored. We can skip the + // test if the user don't want to modify a field (and do not provide the + // value + continue; + if (! in_array ("not null", $params) && + ! array_key_exists ($field, $values)) + continue; + if (in_array ("not null", $params) && + ! array_key_exists ($field, $values)) + { + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' mandatory and not provided"), $field); + continue; + } + if (! is_string ($values[$field]) && ! is_integer ($values[$field]) && + ! is_null ($values[$field])) + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' not a string nor a integer"), $field); + switch ($this->fieldTypeLight ($field)) + { + case "integer": + if (strspn ($values[$field], "0123456789") !== strlen ($values[$field])) + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' not in integer format"), $field); + break; + case "varchar": + $length = $this->fieldLength ($field); + if (mb_strlen ($values[$field]) > $length) + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' : Data field too long"), $field); + break; + case "date": + if (! preg_match ("#^\d{4}-\d{2}-\d{2}$", $values[$field])) + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' not in date format"), $field); + break; + case "datetime": + if (! preg_match ("#^\d{4}-\d{2}-\d{2} \d{2}:\d{2}:\d{2}$#", + $values[$field])) + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' not in datetime format"), $field); + break; + case "time": + if (! preg_match ("#^\d{2}:\d{2}:\d{2}$#", $values[$field])) + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' not in time format"), $field); + break; + default: + $errors[$field] = sprintf (dgettext ("domframework", + "Field '%s' : invalid SQL type (%s) in ". + "\$this->fields "), $field, + $this->fieldTypeLight ($field)); + } + } + + // - Check the unique entries (if defined) + // The primary key is always unique : add it if not set by the user + $this->debugLog (" verify the unique constraint"); + if (! in_array ($this->primary, $this->unique)) + $uniques = array_merge (array ($this->primary), $this->unique); + else + $uniques = $this->unique; + $setValues = $values; + if (! array_key_exists ($this->primary, $setValues)) + $setValues[$this->primary] = null; + foreach ($uniques as $k=>$columns) + { + if ($update !== false && ! isset ($resUpdate)) + { + // Can not update multiple UNIQUE rows with the same value + $this->debugLog ("CLONE because of update"); + $objTmp = clone $this; + $objTmp->debugDepth++; + $objTmp->clearRequest (); + $objTmp->Select (); + $objTmp->displayColumn ($this->primary); + $objTmp->displayColumn ($columns); + $objTmp->whereValues = $this->whereValues; + $objTmp->whereExpression = $this->whereExpression; + $objTmp->limitLines (3); + $resUpdate = $objTmp->execute (); + unset ($objTmp); + if (count ($resUpdate) > 1) + $this->DBException (sprintf (dgettext ("domframework", + "Can't update multiple rows with unique value"), $columns)); + if (count ($resUpdate) === 0) + { + // There is no row available with the WHERE clause provided + // Skip all the UNIQUE tests as there will not have any modification + break; + } + } + + $this->debugLog ("CLONE to check primary and unique constraint"); + $objTmp = clone $this; + $objTmp->debugDepth++; + $objTmp->clearRequest (); + $objTmp->Select (); + $objTmp->displayColumn ($this->primary); + if (is_array ($columns)) + { + // Multiple columns in unique + $objTmp->debugLog (" verify the unique multiple [", + implode (",", $columns),"]"); + foreach ($columns as $column) + { + if (! array_key_exists ($column, $setValues)) + { + if (array_key_exists (0, $resUpdate)) + { + // In UPDATE, if a column is not modified (doesn't appears in + // setValues), use the old value to search + $valTest = $resUpdate[0][$column]; + $objTmp->whereAdd ($column, "=", $valTest); + } + else + $errors[$column] = sprintf (dgettext ("domframework", + "No column '%s' defined but must be unique !"), $column); + } + else + $objTmp->whereAdd ($column, "=", $setValues[$column]); + } + } + else + { + // One column in unique + $objTmp->debugLog (" verify the unique one column [$columns]"); + if (! array_key_exists ($columns, $setValues)) + $errors[$columns] = sprintf (dgettext ("domframework", + "No column '%s' defined but must be unique !"), $columns); + else + $objTmp->whereAdd ($columns, "=", $setValues[$columns]); + } + if ($update && array_key_exists (0, $resUpdate)) + { + // If the value already exists, check if it is the same (the SQL can + // overwrite with the same value) + // If it is not the same, produce an error + $objTmp->whereAdd ($this->primary, "!=", + $resUpdate[0][$this->primary]); + } + if (count ($errors) == 0 && count ($objTmp->execute ())) + $this->DBException (dgettext ("domframework", + "An entry with these values already exists")); + unset ($objTmp); + } + + // - If foreign keys, check if the value is set in the constraint + foreach ($this->foreign as $field=>$params) + { + if (! array_key_exists ($field, $this->setValues)) + $errors[$field] = dgettext ("domframework", + "The field '%s' must be test on foreign, but is not provided"); + if (! array_key_exists ($params[0], $this->setForeignObj)) + $this->DBException (dgettext ("domframework", + "No foreign object configured to test the foreign key")); + $this->debugLog ("CLONE to check foreign constraint [$field]"); + $objTmp = clone $this->setForeignObj[$params[0]]; + $objTmp->debug = $this->debug; + $objTmp->debugDepth++; + $objTmp->clearRequest (); + $objTmp->Select (); + $objTmp->displayColumn ($objTmp->primary); + $objTmp->whereAdd ($params[1], "=", $this->setValues[$field]); + if (count ($objTmp->execute ()) === 0) + $errors[$field] = sprintf (dgettext ("domframework", + "The value of the foreign key '%s' doesn't exists in foreign table"), + $field); + } + return $errors; + } + + /** Check the values before doing really the modification of the database + * @param boolean|null $update if true UPDATE request, else INSERT request + */ + public function checkValues ($update = false) + { + $this->debugLog ("Entering checkValues (",$update,")"); + $update = !! $update; + $values = $this->setValues; + $errors = $this->verify ($values, $update); + if (count ($errors)) + $this->DBException (reset ($errors)); + $this->debugLog ("End of checkValues (",$update,") : Nothing in error"); + } + + /** Execute the pre-defined query + * Return the content array if SELECT command is choosed + * Return the Last ID if INSERT command is choosed + * Return the number of modified lines for UPDATE/DELETE command + */ + public function execute () + { + $this->debugLog ("Entering execute ()"); + switch ($this->command) + { + case "SELECT": + break; + case "INSERT": + $this->checkValues (false); + break; + case "UPDATE": + $this->checkValues (true); + break; + case "DELETE": + break; + default: + $this->DBException ("execute : command not defined : no check"); + } + $this->debugLog ("Entering createRequest ()"); + $sql = $this->createRequest (); + $this->debugLog ("Entering prepareRequest (",$sql,", ",false,")"); + $st = $this->prepareRequest ($sql, false); + $this->debugLog ("'",$this->getDisplayQuery (),"'"); + $st->execute (); + switch ($this->command) + { + case "SELECT": + $result = $st->fetchAll (\PDO::FETCH_ASSOC); + // Harmonize the fetchAll result between all the databases drivers + foreach ($result as &$row) + { + foreach ($row as $col=>&$val) + { + // The fields defined with "integer" type are translated to PHP + // integer type (Already done by PostgreSQL driver, but not by MySQL + // and SQLite + if (strtolower ($this->fields[$col][0]) === "integer") + $val = intval ($val); + } + } + return $result; + case "INSERT": + return self::$instance[$this->dsn]->lastInsertId (); + case "UPDATE": + case "DELETE": + return $st->rowCount (); + default: + $this->DBException ("execute : command not defined : no RC"); + } + } + + /** Error management + * @param string $message The message to throw in the exception + */ + public function DBException ($message) + { + $backtrace = debug_backtrace (); + if (! array_key_exists (1, $backtrace)) + unset ($backtrace); + else + { + $backtrace = end ($backtrace); + $filename = basename ($backtrace["file"]); + $line = $backtrace["line"]; + $method = $backtrace["function"]; + $message .= " ($filename:$line [$method])"; + } + throw new \Exception ($message, 500); + } + + /** Debug function + * @param mixed ...$message The message to display in debug + */ + private function debugLog ($message) + { + if ((!!$this->debug) === false) + return; + echo str_repeat ("=", $this->debugDepth * 2)." "; + foreach (func_get_args() as $nb=>$arg) + { + if (is_string ($arg) || is_int ($arg)) + echo $arg; + elseif (is_bool ($arg) && $arg === true) + echo "true"; + elseif (is_bool ($arg) && $arg === false) + echo "false"; + elseif (is_array ($arg)) + print_r ($arg); + elseif (is_null ($arg)) + echo "NULL"; + else + die ("DEBUG TYPE UNKNOWN ".gettype ($arg)."\n"); + } + echo "\n"; + } +} diff --git a/fts.php b/fts.php new file mode 100644 index 0000000..253dc34 --- /dev/null +++ b/fts.php @@ -0,0 +1,222 @@ + + */ + +/** The Full Text Search + * Analyze the provided search text (like a search engine), and create the + * sql query to found the answer. + * Manage the sentences (enclosed in quotes), or the standalone words, + * Manage the non wanted field (beginning by -), + * Do not search if the word is smaller than a parameter. + */ +class fts +{ + /** The minimum length of a token to search + */ + public $minLength = 3; + + /** The tokens found in the query, with the minus state if the user do not + * want the provided token + */ + private $tokens = null; + + /** The tokens without the too small tokens + */ + private $tokensMin =null; + + /** The regexes created by the parser + */ + private $regexes = null; + + /** Get the tokens store after the search + */ + public function getTokens () + { + return $this->tokens; + } + + /** Get the tokens store after the search, without the too small ones + */ + public function getTokensMin () + { + return $this->tokensMin; + } + + /** Get the regexes defined after the analyzer + */ + public function getRegexes () + { + return $this->regexes; + } + + /** Search the text provided in $query in the database + * @param string $query The text to found in the database + * @return array The operator and the associated regex value to search + */ + public function search ($query) + { + $query = trim ($query); + $this->tokens = $this->tokenizer ($query); + $this->tokensMin = $this->tokenMinLength ($this->tokens["tokens"], + $this->tokens["minuses"]); + $this->regexes = $this->regex ($this->tokensMin["tokens"], + $this->tokensMin["minuses"]); + return $this->regexes; + } + + /** Search in SQL + * @param string $query The text to found in the database + * @param object $dblayeroo The dblayeroo object to query + * @param array|null $fields The fields in $dblayeroo to look for data. If + * null, look in all the fields defined in the dblayeroo object + * @return array The result of the query + */ + public function searchSQL ($query, $dblayeroo, $fields) + { + $regexes = $this->search ($query); + // Clone the object to not modify a previously defined query + $dbl = clone $dblayeroo; + $dbl->clearRequest (); + $dbl->select (); + if ($fields === null) + $fields = array_keys ($dbl->fields ()); + $i = 0; + foreach ($fields as $field) + { + if (! array_key_exists ($field, $dbl->fields ())) + throw new \Exception (sprintf ( + _("The field '%s' doesn't exists in database"), + $field), 500); + if ($i > 0) + $dbl->whereAddOR (); + $dbl->whereAddParenthesisOpen (); + $j = 0; + foreach ($regexes["operator"] as $key=>$operator) + { + if ($j > 0) + $dbl->whereAddAND (); + $dbl->whereAdd ($field, $operator, $regexes["value"][$key]); + $j++; + } + $dbl->whereAddParenthesisClose (); + $i++; + } + return $dbl->execute (); + } + + /** Create the regex associated to the provided tokens and minuses + * @param array $tokens The token list + * @param array $minuses The minuses list + * @return array The operator and the associated regex value to search + */ + private function regex ($tokens, $minuses) + { + if (! is_array ($tokens)) + throw new \Exception ("Invalid tokens provided to fts:tokenMinLength", + 500); + if (! is_array ($minuses)) + throw new \Exception ("Invalid minuses provided to fts:tokenMinLength", + 500); + $operator = array (); + $value = array (); + foreach ($tokens as $key=>$token) + { + if ($minuses[$key] === "-") + $operator[$key] = "NOT REGEXP"; + else + $operator[$key] = "REGEXP"; + $value[$key] = "(^|[<> \(\",.;/:!?])". + preg_quote ($token). + "([<> \)\",.;/:!?]|$)"; + } + return array ("operator"=>$operator, "value"=>$value); + } + + /** Remove the tokens with too small length. Remove the not desired minuses + * too. + * @param array $tokens The token list + * @param array $minuses The minuses list + * @return array tokens and minuses + */ + private function tokenMinLength ($tokens, $minuses) + { + if (! is_array ($tokens)) + throw new \Exception ("Invalid tokens provided to fts:tokenMinLength", + 500); + if (! is_array ($minuses)) + throw new \Exception ("Invalid minuses provided to fts:tokenMinLength", + 500); + $newTokens = array (); + $newMinuses = array (); + foreach ($tokens as $key=>$token) + { + if (mb_strlen ($token) >= $this->minLength) + { + $newTokens[] = $token; + $newMinuses[] = $minuses[$key]; + } + } + return array ("tokens"=>$newTokens, "minuses"=>$newMinuses); + } + + /** Return an array with the $query tokenized + * @param string $query The text to tokenize + * @return array tokens and minuses + */ + private function tokenizer ($query) + { + if (! is_string ($query)) + throw new \Exception ("Invalid query provided to fts:tokenizer", 500); + $debug = false; + $tokens = array (); + $minuses = array (); + // Look for sentences + $offset = 0; + if ($debug) echo "\n012345678901234567890123456789\n$query\n"; + while ($offset <= mb_strlen ($query)) + { + if ($debug) echo "OFFSET=$offset\n"; + if (substr ($query, $offset, 1) === "-") + { + if ($debug) echo "MINUS\n"; + $minus = "-"; + $offset++; + } + else + $minus = ""; + $start = strpos ($query, "\"", $offset); + if ($start === $offset) + { + // Sentence, see if there is a end + $end = strpos ($query, "\"", $offset + 1); + if ($end !== false) + { + // Complete sentence (with ending double quote) + $nbchars = $end - $offset - 1; + if ($debug) + echo "COMPLETE SENTENCE (Start ".($offset+1). + " with $nbchars chars)\n"; + $token = substr ($query, $offset + 1, $nbchars); + $tokens[] = $token; + $minuses[] = $minus; + $offset = $end + 1; + continue; + } + } + // Word analysis + $end = strpos ($query, " ", $offset); + if ($end === false) + $end = strlen ($query); + $nbchars = $end - $offset; + if ($debug) echo "WORD FOUND (Start $offset with $nbchars chars)\n"; + $token = substr ($query, $offset, $nbchars); + $tokens[] = $token; + $minuses[] = $minus; + $offset = $end + 1; + } + if ($debug) print_r ($tokens); + return array ("tokens"=>$tokens, "minuses"=>$minuses); + } +}