Documentation TYPO3 par Ameos

pivottable.inc.php

00001 <?php
00015 /*
00016  * Concept from daniel.lucazeau@ajornet.com. 
00017  *
00018  * @param db            Adodb database connection
00019  * @param tables        List of tables to join
00020  * @rowfields           List of fields to display on each row
00021  * @colfield            Pivot field to slice and display in columns, if we want to calculate
00022  *                                              ranges, we pass in an array (see example2)
00023  * @where                       Where clause. Optional.
00024  * @aggfield            This is the field to sum. Optional. 
00025  *                                              Since 2.3.1, if you can use your own aggregate function 
00026  *                                              instead of SUM, eg. $aggfield = 'fieldname'; $aggfn = 'AVG';
00027  * @sumlabel            Prefix to display in sum columns. Optional.
00028  * @aggfn                       Aggregate function to use (could be AVG, SUM, COUNT)
00029  * @showcount           Show count of records
00030  *
00031  * @returns                     Sql generated
00032  */
00033  
00034  function PivotTableSQL(&$db,$tables,$rowfields,$colfield, $where=false,
00035         $aggfield = false,$sumlabel='Sum ',$aggfn ='SUM', $showcount = true)
00036  {
00037         if ($aggfield) $hidecnt = true;
00038         else $hidecnt = false;
00039         
00040         $iif = strpos($db->databaseType,'access') !== false; 
00041                 // note - vfp still doesn' work even with IIF enabled || $db->databaseType == 'vfp';
00042         
00043         //$hidecnt = false;
00044         
00045         if ($where) $where = "\nWHERE $where";
00046         if (!is_array($colfield)) $colarr = $db->GetCol("select distinct $colfield from $tables $where order by 1");
00047         if (!$aggfield) $hidecnt = false;
00048         
00049         $sel = "$rowfields, ";
00050         if (is_array($colfield)) {
00051                 foreach ($colfield as $k => $v) {
00052                         $k = trim($k);
00053                         if (!$hidecnt) {
00054                                 $sel .= $iif ? 
00055                                         "\n\t$aggfn(IIF($v,1,0)) AS \"$k\", "
00056                                         :
00057                                         "\n\t$aggfn(CASE WHEN $v THEN 1 ELSE 0 END) AS \"$k\", ";
00058                         }
00059                         if ($aggfield) {
00060                                 $sel .= $iif ?
00061                                         "\n\t$aggfn(IIF($v,$aggfield,0)) AS \"$sumlabel$k\", "
00062                                         :
00063                                         "\n\t$aggfn(CASE WHEN $v THEN $aggfield ELSE 0 END) AS \"$sumlabel$k\", ";
00064                         }
00065                 } 
00066         } else {
00067                 foreach ($colarr as $v) {
00068                         if (!is_numeric($v)) $vq = $db->qstr($v);
00069                         else $vq = $v;
00070                         $v = trim($v);
00071                         if (strlen($v) == 0     ) $v = 'null';
00072                         if (!$hidecnt) {
00073                                 $sel .= $iif ?
00074                                         "\n\t$aggfn(IIF($colfield=$vq,1,0)) AS \"$v\", "
00075                                         :
00076                                         "\n\t$aggfn(CASE WHEN $colfield=$vq THEN 1 ELSE 0 END) AS \"$v\", ";
00077                         }
00078                         if ($aggfield) {
00079                                 if ($hidecnt) $label = $v;
00080                                 else $label = "{$v}_$aggfield";
00081                                 $sel .= $iif ?
00082                                         "\n\t$aggfn(IIF($colfield=$vq,$aggfield,0)) AS \"$label\", "
00083                                         :
00084                                         "\n\t$aggfn(CASE WHEN $colfield=$vq THEN $aggfield ELSE 0 END) AS \"$label\", ";
00085                         }
00086                 }
00087         }
00088         if ($aggfield && $aggfield != '1'){
00089                 $agg = "$aggfn($aggfield)";
00090                 $sel .= "\n\t$agg as \"$sumlabel$aggfield\", ";         
00091         }
00092         
00093         if ($showcount)
00094                 $sel .= "\n\tSUM(1) as Total";
00095         else
00096                 $sel = substr($sel,0,strlen($sel)-2);
00097         
00098         $sql = "SELECT $sel \nFROM $tables $where \nGROUP BY $rowfields";
00099         return $sql;
00100  }
00101 
00102 /* EXAMPLES USING MS NORTHWIND DATABASE */
00103 if (0) {
00104 
00105 # example1
00106 #
00107 # Query the main "product" table
00108 # Set the rows to CompanyName and QuantityPerUnit
00109 # and the columns to the Categories
00110 # and define the joins to link to lookup tables 
00111 # "categories" and "suppliers"
00112 #
00113 
00114  $sql = PivotTableSQL(
00115         $gDB,                                                                                   # adodb connection
00116         'products p ,categories c ,suppliers s',                # tables
00117         'CompanyName,QuantityPerUnit',                                  # row fields
00118         'CategoryName',                                                                 # column fields 
00119         'p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID' # joins/where
00120 );
00121  print "<pre>$sql";
00122  $rs = $gDB->Execute($sql);
00123  rs2html($rs);
00124  
00125 /*
00126 Generated SQL:
00127 
00128 SELECT CompanyName,QuantityPerUnit, 
00129         SUM(CASE WHEN CategoryName='Beverages' THEN 1 ELSE 0 END) AS "Beverages", 
00130         SUM(CASE WHEN CategoryName='Condiments' THEN 1 ELSE 0 END) AS "Condiments", 
00131         SUM(CASE WHEN CategoryName='Confections' THEN 1 ELSE 0 END) AS "Confections", 
00132         SUM(CASE WHEN CategoryName='Dairy Products' THEN 1 ELSE 0 END) AS "Dairy Products", 
00133         SUM(CASE WHEN CategoryName='Grains/Cereals' THEN 1 ELSE 0 END) AS "Grains/Cereals", 
00134         SUM(CASE WHEN CategoryName='Meat/Poultry' THEN 1 ELSE 0 END) AS "Meat/Poultry", 
00135         SUM(CASE WHEN CategoryName='Produce' THEN 1 ELSE 0 END) AS "Produce", 
00136         SUM(CASE WHEN CategoryName='Seafood' THEN 1 ELSE 0 END) AS "Seafood", 
00137         SUM(1) as Total 
00138 FROM products p ,categories c ,suppliers s  WHERE p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID 
00139 GROUP BY CompanyName,QuantityPerUnit
00140 */
00141 //=====================================================================
00142 
00143 # example2
00144 #
00145 # Query the main "product" table
00146 # Set the rows to CompanyName and QuantityPerUnit
00147 # and the columns to the UnitsInStock for diiferent ranges
00148 # and define the joins to link to lookup tables 
00149 # "categories" and "suppliers"
00150 #
00151  $sql = PivotTableSQL(
00152         $gDB,                                                                           # adodb connection
00153         'products p ,categories c ,suppliers s',        # tables
00154         'CompanyName,QuantityPerUnit',                          # row fields
00155                                                                                                 # column ranges
00156 array(                                                                          
00157 ' 0 ' => 'UnitsInStock <= 0',
00158 "1 to 5" => '0 < UnitsInStock and UnitsInStock <= 5',
00159 "6 to 10" => '5 < UnitsInStock and UnitsInStock <= 10',
00160 "11 to 15"  => '10 < UnitsInStock and UnitsInStock <= 15',
00161 "16+" =>'15 < UnitsInStock'
00162 ),
00163         ' p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID', # joins/where
00164         'UnitsInStock',                                                         # sum this field
00165         'Sum'                                                                           # sum label prefix
00166 );
00167  print "<pre>$sql";
00168  $rs = $gDB->Execute($sql);
00169  rs2html($rs);
00170  /*
00171  Generated SQL:
00172  
00173 SELECT CompanyName,QuantityPerUnit, 
00174         SUM(CASE WHEN UnitsInStock <= 0 THEN UnitsInStock ELSE 0 END) AS "Sum  0 ", 
00175         SUM(CASE WHEN 0 < UnitsInStock and UnitsInStock <= 5 THEN UnitsInStock ELSE 0 END) AS "Sum 1 to 5", 
00176         SUM(CASE WHEN 5 < UnitsInStock and UnitsInStock <= 10 THEN UnitsInStock ELSE 0 END) AS "Sum 6 to 10", 
00177         SUM(CASE WHEN 10 < UnitsInStock and UnitsInStock <= 15 THEN UnitsInStock ELSE 0 END) AS "Sum 11 to 15", 
00178         SUM(CASE WHEN 15 < UnitsInStock THEN UnitsInStock ELSE 0 END) AS "Sum 16+",
00179         SUM(UnitsInStock) AS "Sum UnitsInStock", 
00180         SUM(1) as Total 
00181 FROM products p ,categories c ,suppliers s  WHERE  p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID 
00182 GROUP BY CompanyName,QuantityPerUnit
00183  */
00184 }
00185 ?>


Généré par L'expert TYPO3 avec  doxygen 1.4.6