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