pivottable.inc.php 6.2 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188
  1. <?php
  2. /**
  3. * @version v5.20.17 31-Mar-2020
  4. * @copyright (c) 2000-2013 John Lim (jlim#natsoft.com). All rights reserved.
  5. * @copyright (c) 2014 Damien Regad, Mark Newnham and the ADOdb community
  6. * Released under both BSD license and Lesser GPL library license.
  7. * Whenever there is any discrepancy between the two licenses,
  8. * the BSD license will take precedence.
  9. *
  10. * Set tabs to 4 for best viewing.
  11. *
  12. */
  13. /*
  14. * Concept from daniel.lucazeau@ajornet.com.
  15. *
  16. * @param db Adodb database connection
  17. * @param tables List of tables to join
  18. * @rowfields List of fields to display on each row
  19. * @colfield Pivot field to slice and display in columns, if we want to calculate
  20. * ranges, we pass in an array (see example2)
  21. * @where Where clause. Optional.
  22. * @aggfield This is the field to sum. Optional.
  23. * Since 2.3.1, if you can use your own aggregate function
  24. * instead of SUM, eg. $aggfield = 'fieldname'; $aggfn = 'AVG';
  25. * @sumlabel Prefix to display in sum columns. Optional.
  26. * @aggfn Aggregate function to use (could be AVG, SUM, COUNT)
  27. * @showcount Show count of records
  28. *
  29. * @returns Sql generated
  30. */
  31. function PivotTableSQL(&$db,$tables,$rowfields,$colfield, $where=false,
  32. $aggfield = false,$sumlabel='Sum ',$aggfn ='SUM', $showcount = true)
  33. {
  34. if ($aggfield) $hidecnt = true;
  35. else $hidecnt = false;
  36. $iif = strpos($db->databaseType,'access') !== false;
  37. // note - vfp 6 still doesn' work even with IIF enabled || $db->databaseType == 'vfp';
  38. //$hidecnt = false;
  39. if ($where) $where = "\nWHERE $where";
  40. if (!is_array($colfield)) $colarr = $db->GetCol("select distinct $colfield from $tables $where order by 1");
  41. if (!$aggfield) $hidecnt = false;
  42. $sel = "$rowfields, ";
  43. if (is_array($colfield)) {
  44. foreach ($colfield as $k => $v) {
  45. $k = trim($k);
  46. if (!$hidecnt) {
  47. $sel .= $iif ?
  48. "\n\t$aggfn(IIF($v,1,0)) AS \"$k\", "
  49. :
  50. "\n\t$aggfn(CASE WHEN $v THEN 1 ELSE 0 END) AS \"$k\", ";
  51. }
  52. if ($aggfield) {
  53. $sel .= $iif ?
  54. "\n\t$aggfn(IIF($v,$aggfield,0)) AS \"$sumlabel$k\", "
  55. :
  56. "\n\t$aggfn(CASE WHEN $v THEN $aggfield ELSE 0 END) AS \"$sumlabel$k\", ";
  57. }
  58. }
  59. } else {
  60. foreach ($colarr as $v) {
  61. if (!is_numeric($v)) $vq = $db->qstr($v);
  62. else $vq = $v;
  63. $v = trim($v);
  64. if (strlen($v) == 0 ) $v = 'null';
  65. if (!$hidecnt) {
  66. $sel .= $iif ?
  67. "\n\t$aggfn(IIF($colfield=$vq,1,0)) AS \"$v\", "
  68. :
  69. "\n\t$aggfn(CASE WHEN $colfield=$vq THEN 1 ELSE 0 END) AS \"$v\", ";
  70. }
  71. if ($aggfield) {
  72. if ($hidecnt) $label = $v;
  73. else $label = "{$v}_$aggfield";
  74. $sel .= $iif ?
  75. "\n\t$aggfn(IIF($colfield=$vq,$aggfield,0)) AS \"$label\", "
  76. :
  77. "\n\t$aggfn(CASE WHEN $colfield=$vq THEN $aggfield ELSE 0 END) AS \"$label\", ";
  78. }
  79. }
  80. }
  81. if ($aggfield && $aggfield != '1'){
  82. $agg = "$aggfn($aggfield)";
  83. $sel .= "\n\t$agg as \"$sumlabel$aggfield\", ";
  84. }
  85. if ($showcount)
  86. $sel .= "\n\tSUM(1) as Total";
  87. else
  88. $sel = substr($sel,0,strlen($sel)-2);
  89. // Strip aliases
  90. $rowfields = preg_replace('/ AS (\w+)/i', '', $rowfields);
  91. $sql = "SELECT $sel \nFROM $tables $where \nGROUP BY $rowfields";
  92. return $sql;
  93. }
  94. /* EXAMPLES USING MS NORTHWIND DATABASE */
  95. if (0) {
  96. # example1
  97. #
  98. # Query the main "product" table
  99. # Set the rows to CompanyName and QuantityPerUnit
  100. # and the columns to the Categories
  101. # and define the joins to link to lookup tables
  102. # "categories" and "suppliers"
  103. #
  104. $sql = PivotTableSQL(
  105. $gDB, # adodb connection
  106. 'products p ,categories c ,suppliers s', # tables
  107. 'CompanyName,QuantityPerUnit', # row fields
  108. 'CategoryName', # column fields
  109. 'p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID' # joins/where
  110. );
  111. print "<pre>$sql";
  112. $rs = $gDB->Execute($sql);
  113. rs2html($rs);
  114. /*
  115. Generated SQL:
  116. SELECT CompanyName,QuantityPerUnit,
  117. SUM(CASE WHEN CategoryName='Beverages' THEN 1 ELSE 0 END) AS "Beverages",
  118. SUM(CASE WHEN CategoryName='Condiments' THEN 1 ELSE 0 END) AS "Condiments",
  119. SUM(CASE WHEN CategoryName='Confections' THEN 1 ELSE 0 END) AS "Confections",
  120. SUM(CASE WHEN CategoryName='Dairy Products' THEN 1 ELSE 0 END) AS "Dairy Products",
  121. SUM(CASE WHEN CategoryName='Grains/Cereals' THEN 1 ELSE 0 END) AS "Grains/Cereals",
  122. SUM(CASE WHEN CategoryName='Meat/Poultry' THEN 1 ELSE 0 END) AS "Meat/Poultry",
  123. SUM(CASE WHEN CategoryName='Produce' THEN 1 ELSE 0 END) AS "Produce",
  124. SUM(CASE WHEN CategoryName='Seafood' THEN 1 ELSE 0 END) AS "Seafood",
  125. SUM(1) as Total
  126. FROM products p ,categories c ,suppliers s WHERE p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID
  127. GROUP BY CompanyName,QuantityPerUnit
  128. */
  129. //=====================================================================
  130. # example2
  131. #
  132. # Query the main "product" table
  133. # Set the rows to CompanyName and QuantityPerUnit
  134. # and the columns to the UnitsInStock for diiferent ranges
  135. # and define the joins to link to lookup tables
  136. # "categories" and "suppliers"
  137. #
  138. $sql = PivotTableSQL(
  139. $gDB, # adodb connection
  140. 'products p ,categories c ,suppliers s', # tables
  141. 'CompanyName,QuantityPerUnit', # row fields
  142. # column ranges
  143. array(
  144. ' 0 ' => 'UnitsInStock <= 0',
  145. "1 to 5" => '0 < UnitsInStock and UnitsInStock <= 5',
  146. "6 to 10" => '5 < UnitsInStock and UnitsInStock <= 10',
  147. "11 to 15" => '10 < UnitsInStock and UnitsInStock <= 15',
  148. "16+" =>'15 < UnitsInStock'
  149. ),
  150. ' p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID', # joins/where
  151. 'UnitsInStock', # sum this field
  152. 'Sum' # sum label prefix
  153. );
  154. print "<pre>$sql";
  155. $rs = $gDB->Execute($sql);
  156. rs2html($rs);
  157. /*
  158. Generated SQL:
  159. SELECT CompanyName,QuantityPerUnit,
  160. SUM(CASE WHEN UnitsInStock <= 0 THEN UnitsInStock ELSE 0 END) AS "Sum 0 ",
  161. SUM(CASE WHEN 0 < UnitsInStock and UnitsInStock <= 5 THEN UnitsInStock ELSE 0 END) AS "Sum 1 to 5",
  162. SUM(CASE WHEN 5 < UnitsInStock and UnitsInStock <= 10 THEN UnitsInStock ELSE 0 END) AS "Sum 6 to 10",
  163. SUM(CASE WHEN 10 < UnitsInStock and UnitsInStock <= 15 THEN UnitsInStock ELSE 0 END) AS "Sum 11 to 15",
  164. SUM(CASE WHEN 15 < UnitsInStock THEN UnitsInStock ELSE 0 END) AS "Sum 16+",
  165. SUM(UnitsInStock) AS "Sum UnitsInStock",
  166. SUM(1) as Total
  167. FROM products p ,categories c ,suppliers s WHERE p.CategoryID = c.CategoryID and s.SupplierID= p.SupplierID
  168. GROUP BY CompanyName,QuantityPerUnit
  169. */
  170. }