From c953d0260484b1907911c67d36bba06d4031886f Mon Sep 17 00:00:00 2001 From: Uwe Steinmann Date: Thu, 27 Jul 2017 12:34:46 +0200 Subject: [PATCH] views instead of temp. tables can be used This speeds up many sql statements for mysql and pgsql --- SeedDMS_Core/Core/inc.DBAccessPDO.php | 295 +++++++++++++++++++++++++- 1 file changed, 293 insertions(+), 2 deletions(-) diff --git a/SeedDMS_Core/Core/inc.DBAccessPDO.php b/SeedDMS_Core/Core/inc.DBAccessPDO.php index f3d98d383..16d031a74 100644 --- a/SeedDMS_Core/Core/inc.DBAccessPDO.php +++ b/SeedDMS_Core/Core/inc.DBAccessPDO.php @@ -112,6 +112,11 @@ class SeedDMS_Core_DatabaseAccess { */ private $_logfp; + /** + * @var boolean set to true if views instead of temp. tables shall be used + */ + private $_useviews; + /** * Return list of all database tables * @@ -140,6 +145,34 @@ class SeedDMS_Core_DatabaseAccess { return $res; } /* }}} */ + /** + * Return list of all database views + * + * This function is used to retrieve a list of database views + * + * @return array list of view names + */ + public function ViewList() { /* {{{ */ + switch($this->_driver) { + case 'mysql': + $sql = "select TABLE_NAME as name from information_schema.views where TABLE_SCHEMA='".$this->_database."'"; + break; + case 'sqlite': + $sql = "select tbl_name as name from sqlite_master where type='view'"; + break; + case 'pgsql': + $sql = "select viewname as name from pg_catalog.pg_views where schemaname='public'"; + break; + default: + return false; + } + $arr = $this->getResultArray($sql); + $res = array(); + foreach($arr as $tmp) + $res[] = $tmp['name']; + return $res; + } /* }}} */ + /** * Constructor of SeedDMS_Core_DatabaseAccess * @@ -183,6 +216,7 @@ class SeedDMS_Core_DatabaseAccess { $this->_ttcontentid = false; $this->_ttreceiptid = false; $this->_ttrevisionid = false; + $this->_useviews = true; $this->_debug = false; } /* }}} */ @@ -240,6 +274,15 @@ class SeedDMS_Core_DatabaseAccess { $this->_conn->exec('PRAGMA foreign_keys = ON'); break; } + if($this->_useviews) { + $tmp = $this->ViewList(); + foreach(array('ttreviewid', 'ttapproveid', 'ttstatid', 'ttcontentid', 'ttreceiptid', 'ttrevisionid') as $viewname) { + if(in_array($viewname, $tmp)) { + $this->{"_".$viewname} = true; + } + } + } + $this->_connected = true; return true; } /* }}} */ @@ -383,7 +426,7 @@ class SeedDMS_Core_DatabaseAccess { /** * Create various temporary tables to speed up and simplify sql queries */ - function createTemporaryTable($tableName, $override=false) { /* {{{ */ + private function __createTemporaryTable($tableName, $override=false) { /* {{{ */ if (!strcasecmp($tableName, "ttreviewid")) { switch($this->_driver) { case 'sqlite': @@ -559,7 +602,7 @@ class SeedDMS_Core_DatabaseAccess { // "ORDER BY `maxLogID`"; break; case 'pgsql': - $queryStr = "CREATE TEMPORARY TABLE IF NOT EXISTS `ttreceiptid` (`receiptID` INTEGER, `maxLogID` INTEGER, PRIMARY KEY (`receiptID`);". + $queryStr = "CREATE TEMPORARY TABLE IF NOT EXISTS `ttreceiptid` (`receiptID` INTEGER, `maxLogID` INTEGER, PRIMARY KEY (`receiptID`));". "INSERT INTO `ttreceiptid` SELECT `tblDocumentReceiptLog`.`receiptID`, ". "MAX(`tblDocumentReceiptLog`.`receiptLogID`) AS `maxLogID` ". "FROM `tblDocumentReceiptLog` ". @@ -633,6 +676,254 @@ class SeedDMS_Core_DatabaseAccess { return false; } /* }}} */ + /** + * Create various temporary tables to speed up and simplify sql queries + */ + private function __createView($tableName, $override=false) { /* {{{ */ + if (!strcasecmp($tableName, "ttreviewid")) { + switch($this->_driver) { + case 'sqlite': + $queryStr = "CREATE VIEW `ttreviewid` AS ". + "SELECT `tblDocumentReviewLog`.`reviewID` AS `reviewID`, ". + "MAX(`tblDocumentReviewLog`.`reviewLogID`) AS `maxLogID` ". + "FROM `tblDocumentReviewLog` ". + "GROUP BY `tblDocumentReviewLog`.`reviewID` "; //. + break; + case 'pgsql': + $queryStr = "CREATE VIEW `ttreviewid` AS ". + "SELECT `tblDocumentReviewLog`.`reviewID` AS `reviewID`, ". + "MAX(`tblDocumentReviewLog`.`reviewLogID`) AS `maxLogID` ". + "FROM `tblDocumentReviewLog` ". + "GROUP BY `tblDocumentReviewLog`.`reviewID` "; + break; + default: + $queryStr = "CREATE".($override ? " OR REPLACE" : "")." VIEW `ttreviewid` AS ". + "SELECT `tblDocumentReviewLog`.`reviewID` AS `reviewID`, ". + "MAX(`tblDocumentReviewLog`.`reviewLogID`) AS `maxLogID` ". + "FROM `tblDocumentReviewLog` ". + "GROUP BY `tblDocumentReviewLog`.`reviewID` "; + } + if (!$this->_ttreviewid) { + if (!$this->getResult($queryStr)) + return false; + $this->_ttreviewid=true; + } + else { + if (is_bool($override) && $override) { + if (!$this->getResult("DROP VIEW `ttreviewid`")) + return false; + if (!$this->getResult($queryStr)) + return false; + } + } + return $this->_ttreviewid; + } + elseif (!strcasecmp($tableName, "ttapproveid")) { + switch($this->_driver) { + case 'sqlite': + $queryStr = "CREATE VIEW `ttapproveid` AS ". + "SELECT `tblDocumentApproveLog`.`approveID` AS `approveID`, ". + "MAX(`tblDocumentApproveLog`.`approveLogID`) AS `maxLogID` ". + "FROM `tblDocumentApproveLog` ". + "GROUP BY `tblDocumentApproveLog`.`approveID` "; //. + break; + case 'pgsql': + $queryStr = "CREATE VIEW `ttapproveid` AS ". + "SELECT `tblDocumentApproveLog`.`approveID` AS `approveID`, ". + "MAX(`tblDocumentApproveLog`.`approveLogID`) AS `maxLogID` ". + "FROM `tblDocumentApproveLog` ". + "GROUP BY `tblDocumentApproveLog`.`approveID` "; + break; + default: + $queryStr = "CREATE".($override ? " OR REPLACE" : "")." VIEW `ttapproveid` AS ". + "SELECT `tblDocumentApproveLog`.`approveID`, ". + "MAX(`tblDocumentApproveLog`.`approveLogID`) AS `maxLogID` ". + "FROM `tblDocumentApproveLog` ". + "GROUP BY `tblDocumentApproveLog`.`approveID` "; + } + if (!$this->_ttapproveid) { + if (!$this->getResult($queryStr)) + return false; + $this->_ttapproveid=true; + } + else { + if (is_bool($override) && $override) { + if (!$this->getResult("DROP VIEW `ttapproveid`")) + return false; + if (!$this->getResult($queryStr)) + return false; + } + } + return $this->_ttapproveid; + } + elseif (!strcasecmp($tableName, "ttstatid")) { + switch($this->_driver) { + case 'sqlite': + $queryStr = "CREATE VIEW `ttstatid` AS ". + "SELECT `tblDocumentStatusLog`.`statusID` AS `statusID`, ". + "MAX(`tblDocumentStatusLog`.`statusLogID`) AS `maxLogID` ". + "FROM `tblDocumentStatusLog` ". + "GROUP BY `tblDocumentStatusLog`.`statusID` "; + break; + case 'pgsql': + $queryStr = "CREATE VIEW `ttstatid` AS ". + "SELECT `tblDocumentStatusLog`.`statusID` AS `statusID`, ". + "MAX(`tblDocumentStatusLog`.`statusLogID`) AS `maxLogID` ". + "FROM `tblDocumentStatusLog` ". + "GROUP BY `tblDocumentStatusLog`.`statusID` "; + break; + default: + $queryStr = "CREATE".($override ? " OR REPLACE" : "")." VIEW `ttstatid` AS ". + "SELECT `tblDocumentStatusLog`.`statusID`, ". + "MAX(`tblDocumentStatusLog`.`statusLogID`) AS `maxLogID` ". + "FROM `tblDocumentStatusLog` ". + "GROUP BY `tblDocumentStatusLog`.`statusID` "; + } + if (!$this->_ttstatid) { + if (!$this->getResult($queryStr)) + return false; + $this->_ttstatid=true; + } + else { + if (is_bool($override) && $override) { + if (!$this->getResult("DROP VIEW `ttstatid`")) + return false; + if (!$this->getResult($queryStr)) + return false; + } + } + return $this->_ttstatid; + } + elseif (!strcasecmp($tableName, "ttcontentid")) { + switch($this->_driver) { + case 'sqlite': + $queryStr = "CREATE VIEW `ttcontentid` AS ". + "SELECT `tblDocumentContent`.`document` AS `document`, ". + "MAX(`tblDocumentContent`.`version`) AS `maxVersion` ". + "FROM `tblDocumentContent` ". + "GROUP BY `tblDocumentContent`.`document` ". + "ORDER BY `tblDocumentContent`.`document`"; + break; + case 'pgsql': + $queryStr = "CREATE VIEW `ttcontentid` AS ". + "SELECT `tblDocumentContent`.`document` AS `document`, ". + "MAX(`tblDocumentContent`.`version`) AS `maxVersion` ". + "FROM `tblDocumentContent` ". + "GROUP BY `tblDocumentContent`.`document` ". + "ORDER BY `tblDocumentContent`.`document`"; + break; + default: + $queryStr = "CREATE".($override ? " OR REPLACE" : "")." VIEW `ttcontentid` AS ". + "SELECT `tblDocumentContent`.`document`, ". + "MAX(`tblDocumentContent`.`version`) AS `maxVersion` ". + "FROM `tblDocumentContent` ". + "GROUP BY `tblDocumentContent`.`document` ". + "ORDER BY `tblDocumentContent`.`document`"; + } + if (!$this->_ttcontentid) { + if (!$this->getResult($queryStr)) + return false; + $this->_ttcontentid=true; + } + else { + if (is_bool($override) && $override) { + if (!$this->getResult("DROP VIEW `ttcontentid`")) + return false; + if (!$this->getResult($queryStr)) + return false; + } + } + return $this->_ttcontentid; + } + elseif (!strcasecmp($tableName, "ttreceiptid")) { + switch($this->_driver) { + case 'sqlite': + $queryStr = "CREATE VIEW `ttreceiptid` AS ". + "SELECT `tblDocumentReceiptLog`.`receiptID` AS `receiptID`, ". + "MAX(`tblDocumentReceiptLog`.`receiptLogID`) AS `maxLogID` ". + "FROM `tblDocumentReceiptLog` ". + "GROUP BY `tblDocumentReceiptLog`.`receiptID` "; + break; + case 'pgsql': + $queryStr = "CREATE VIEW `ttreceiptid` AS ". + "SELECT `tblDocumentReceiptLog`.`receiptID` AS `receiptID`, ". + "MAX(`tblDocumentReceiptLog`.`receiptLogID`) AS `maxLogID` ". + "FROM `tblDocumentReceiptLog` ". + "GROUP BY `tblDocumentReceiptLog`.`receiptID` "; + break; + default: + $queryStr = "CREATE".($override ? " OR REPLACE" : "")." VIEW `ttreceiptid` AS ". + "SELECT `tblDocumentReceiptLog`.`receiptID`, ". + "MAX(`tblDocumentReceiptLog`.`receiptLogID`) AS `maxLogID` ". + "FROM `tblDocumentReceiptLog` ". + "GROUP BY `tblDocumentReceiptLog`.`receiptID` "; + } + if (!$this->_ttreceiptid) { + if (!$this->getResult($queryStr)) + return false; + $this->_ttreceiptid=true; + } + else { + if (is_bool($override) && $override) { + if (!$this->getResult("DROP VIEW `ttreceiptid`")) + return false; + if (!$this->getResult($queryStr)) + return false; + } + } + return $this->_ttreceiptid; + } + elseif (!strcasecmp($tableName, "ttrevisionid")) { + switch($this->_driver) { + case 'sqlite': + $queryStr = "CREATE VIEW `ttrevisionid` AS ". + "SELECT `tblDocumentRevisionLog`.`revisionID` AS `revisionID`, ". + "MAX(`tblDocumentRevisionLog`.`revisionLogID`) AS `maxLogID` ". + "FROM `tblDocumentRevisionLog` ". + "GROUP BY `tblDocumentRevisionLog`.`revisionID` "; + break; + case 'pgsql': + $queryStr = "CREATE VIEW `ttrevisionid` AS ". + "SELECT `tblDocumentRevisionLog`.`revisionID` AS `revisionID`, ". + "MAX(`tblDocumentRevisionLog`.`revisionLogID`) AS `maxLogID` ". + "FROM `tblDocumentRevisionLog` ". + "GROUP BY `tblDocumentRevisionLog`.`revisionID` "; + break; + default: + $queryStr = "CREATE".($override ? " OR REPLACE" : "")." VIEW `ttrevisionid` AS ". + "SELECT `tblDocumentRevisionLog`.`revisionID`, ". + "MAX(`tblDocumentRevisionLog`.`revisionLogID`) AS `maxLogID` ". + "FROM `tblDocumentRevisionLog` ". + "GROUP BY `tblDocumentRevisionLog`.`revisionID` "; + } + if (!$this->_ttrevisionid) { + if (!$this->getResult($queryStr)) + return false; + $this->_ttrevisionid=true; + } + else { + if (is_bool($override) && $override) { + if (!$this->getResult("DROP VIEW `ttrevisionid`")) + return false; + if (!$this->getResult($queryStr)) + return false; + } + } + return $this->_ttrevisionid; + } + return false; + } /* }}} */ + + /** + * Create various temporary tables to speed up and simplify sql queries + */ + public function createTemporaryTable($tableName, $override=false) { /* {{{ */ + if($this->_useviews) + return $this->__createView($tableName, $override); + else + return $this->__createTemporaryTable($tableName, $override); + } /* }}} */ + /** * Return sql statement for extracting the date part from a field * containing a unix timestamp