Preparation for Excel Writer continued
[fa-stable.git] / reporting / rep302.php
1 <?php
2 /**********************************************************************
3     Copyright (C) FrontAccounting, LLC.
4         Released under the terms of the GNU General Public License, GPL, 
5         as published by the Free Software Foundation, either version 3 
6         of the License, or (at your option) any later version.
7     This program is distributed in the hope that it will be useful,
8     but WITHOUT ANY WARRANTY; without even the implied warranty of
9     MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.  
10     See the License here <http://www.gnu.org/licenses/gpl-3.0.html>.
11 ***********************************************************************/
12 $page_security = 2;
13 // ----------------------------------------------------------------
14 // $ Revision:  2.0 $
15 // Creator:     Joe Hunt
16 // date_:       2005-05-19
17 // Title:       Inventory Planning
18 // ----------------------------------------------------------------
19 $path_to_root="..";
20
21 include_once($path_to_root . "/includes/session.inc");
22 include_once($path_to_root . "/includes/date_functions.inc");
23 include_once($path_to_root . "/includes/data_checks.inc");
24 include_once($path_to_root . "/gl/includes/gl_db.inc");
25 include_once($path_to_root . "/inventory/includes/db/items_category_db.inc");
26
27 //----------------------------------------------------------------------------------------------------
28
29 // trial_inquiry_controls();
30 print_inventory_planning();
31
32 function getTransactions($category, $location)
33 {
34         $sql = "SELECT ".TB_PREF."stock_master.category_id,
35                         ".TB_PREF."stock_category.description AS cat_description,
36                         ".TB_PREF."stock_master.stock_id,
37                         ".TB_PREF."stock_master.description,
38                         IF(".TB_PREF."stock_moves.stock_id IS NULL, '', ".TB_PREF."stock_moves.loc_code) AS loc_code,
39                         SUM(IF(".TB_PREF."stock_moves.stock_id IS NULL,0,".TB_PREF."stock_moves.qty)) AS qty_on_hand
40                 FROM (".TB_PREF."stock_master,
41                         ".TB_PREF."stock_category)
42                 LEFT JOIN ".TB_PREF."stock_moves ON
43                         (".TB_PREF."stock_master.stock_id=".TB_PREF."stock_moves.stock_id OR ".TB_PREF."stock_master.stock_id IS NULL)
44                 WHERE ".TB_PREF."stock_master.category_id=".TB_PREF."stock_category.category_id
45                 AND (".TB_PREF."stock_master.mb_flag='B' OR ".TB_PREF."stock_master.mb_flag='M')";
46         if ($category != 0)
47                 $sql .= " AND ".TB_PREF."stock_master.category_id = '$category'";
48         if ($location != 'all')
49                 $sql .= " AND ".TB_PREF."stock_moves.loc_code = '$location'";
50         $sql .= " GROUP BY ".TB_PREF."stock_master.category_id,
51                 ".TB_PREF."stock_category.description,
52                 ".TB_PREF."stock_master.stock_id,
53                 ".TB_PREF."stock_master.description
54                 ORDER BY ".TB_PREF."stock_master.category_id,
55                 ".TB_PREF."stock_master.stock_id";
56
57     return db_query($sql,"No transactions were returned");
58
59 }
60
61 function getCustQty($stockid, $location)
62 {
63         $sql = "SELECT SUM(".TB_PREF."sales_order_details.quantity - ".TB_PREF."sales_order_details.qty_sent) AS qty_demand
64                                 FROM ".TB_PREF."sales_order_details,
65                                         ".TB_PREF."sales_orders
66                                 WHERE ".TB_PREF."sales_order_details.order_no=".TB_PREF."sales_orders.order_no AND ";
67         if ($location != "")
68                 $sql .= TB_PREF."sales_orders.from_stk_loc ='$location' AND ";
69         $sql .= TB_PREF."sales_order_details.stk_code = '$stockid'";
70
71     $TransResult = db_query($sql,"No transactions were returned");
72         $DemandRow = db_fetch($TransResult);
73         return $DemandRow['qty_demand'];
74 }
75
76 function getCustAsmQty($stockid, $location)
77 {
78         $sql = "SELECT SUM((".TB_PREF."sales_order_details.quantity-".TB_PREF."sales_order_details.qty_sent)*".TB_PREF."bom.quantity)
79                                    AS Dem
80                                    FROM ".TB_PREF."sales_order_details,
81                                                 ".TB_PREF."sales_orders,
82                                                 ".TB_PREF."bom,
83                                                 ".TB_PREF."stock_master
84                                    WHERE ".TB_PREF."sales_order_details.stk_code=".TB_PREF."bom.parent AND
85                                    ".TB_PREF."sales_orders.order_no = ".TB_PREF."sales_order_details.order_no AND ";
86         if ($location != "")
87                 $sql .= TB_PREF."sales_orders.from_stk_loc ='$location' AND ";
88         $sql .= TB_PREF."sales_order_details.quantity-".TB_PREF."sales_order_details.qty_sent > 0 AND
89                                    ".TB_PREF."bom.component='$stockid' AND
90                                    ".TB_PREF."stock_master.stock_id=".TB_PREF."bom.parent AND
91                                    ".TB_PREF."stock_master.mb_flag='A'";
92
93     $TransResult = db_query($sql,"No transactions were returned");
94         if (db_num_rows($TransResult) == 1)
95         {
96                 $DemandRow = db_fetch_row($TransResult);
97                 $DemandQty = $DemandRow[0];
98         }
99         else
100                 $DemandQty = 0.0;
101
102     return $DemandQty;
103 }
104
105 function getSuppQty($stockid, $location)
106 {
107         $sql = "SELECT SUM(".TB_PREF."purch_order_details.quantity_ordered - ".TB_PREF."purch_order_details.quantity_received) AS QtyOnOrder
108                                 FROM ".TB_PREF."purch_order_details,
109                                         ".TB_PREF."purch_orders
110                                 WHERE ".TB_PREF."purch_order_details.order_no = ".TB_PREF."purch_orders.order_no
111                                 AND ".TB_PREF."purch_order_details.item_code = '$stockid'";
112         if ($location != "")                    
113                 $sql .= " AND ".TB_PREF."purch_orders.into_stock_location= '$location'";
114
115     $TransResult = db_query($sql,"No transactions were returned");
116         $DemandRow = db_fetch($TransResult);
117         return $DemandRow['QtyOnOrder'];
118 }
119
120 function getPeriods($stockid, $location)
121 {
122         $date5 = date('Y-m-d');
123         $date4 = date('Y-m-d',mktime(0,0,0,date('m'),1,date('Y')));
124         $date3 = date('Y-m-d',mktime(0,0,0,date('m')-1,1,date('Y')));
125         $date2 = date('Y-m-d',mktime(0,0,0,date('m')-2,1,date('Y')));
126         $date1 = date('Y-m-d',mktime(0,0,0,date('m')-3,1,date('Y')));
127         $date0 = date('Y-m-d',mktime(0,0,0,date('m')-4,1,date('Y')));
128
129         $sql = "SELECT SUM(CASE WHEN tran_date >= '$date0' AND tran_date < '$date1' THEN -qty ELSE 0 END) AS prd0,
130                                 SUM(CASE WHEN tran_date >= '$date1' AND tran_date < '$date2' THEN -qty ELSE 0 END) AS prd1,
131                                 SUM(CASE WHEN tran_date >= '$date2' AND tran_date < '$date3' THEN -qty ELSE 0 END) AS prd2,
132                                 SUM(CASE WHEN tran_date >= '$date3' AND tran_date < '$date4' THEN -qty ELSE 0 END) AS prd3,
133                                 SUM(CASE WHEN tran_date >= '$date4' AND tran_date <= '$date5' THEN -qty ELSE 0 END) AS prd4
134                         FROM ".TB_PREF."stock_moves
135                         WHERE stock_id='$stockid'
136                         AND loc_code ='$location'
137                         AND (type=13 OR type=11)
138                         AND visible=1";
139
140     $TransResult = db_query($sql,"No transactions were returned");
141         return db_fetch($TransResult);
142 }
143
144 //----------------------------------------------------------------------------------------------------
145
146 function print_inventory_planning()
147 {
148     global $path_to_root;
149
150     $category = $_POST['PARAM_0'];
151     $location = $_POST['PARAM_1'];
152     $comments = $_POST['PARAM_2'];
153         $destination = $_POST['PARAM_3'];
154         if ($destination)
155         {
156                 include_once($path_to_root . "/reporting/includes/excel_report.inc");
157                 $filename = "InventoryPlanning.xml";
158         }       
159         else
160         {
161                 include_once($path_to_root . "/reporting/includes/pdf_report.inc");
162                 $filename = "InventoryPlanning.pdf";
163         }
164
165         if ($category == reserved_words::get_all_numeric())
166                 $category = 0;
167         if ($category == 0)
168                 $cat = _('All');
169         else
170                 $cat = get_category_name($category);
171
172         if ($location == reserved_words::get_all())
173                 $location = 'all';
174         if ($location == 'all')
175                 $loc = _('All');
176         else
177                 $loc = $location;
178
179         $cols = array(0, 50, 150, 180, 210, 240, 270, 300, 330, 390, 435, 480, 525);
180
181         $per0 = strftime('%b',mktime(0,0,0,date('m'),1,date('Y')));
182         $per1 = strftime('%b',mktime(0,0,0,date('m')-1,1,date('Y')));
183         $per2 = strftime('%b',mktime(0,0,0,date('m')-2,1,date('Y')));
184         $per3 = strftime('%b',mktime(0,0,0,date('m')-3,1,date('Y')));
185         $per4 = strftime('%b',mktime(0,0,0,date('m')-4,1,date('Y')));
186
187         $headers = array(_('Category'), '', $per4, $per3, $per2, $per1, $per0, '3*M',
188                 _('QOH'), _('Cust Ord'), _('Supp Ord'), _('Sugg Ord'));
189
190         $aligns = array('left', 'left', 'right', 'right', 'right', 'right', 'right', 'right',
191                 'right', 'right', 'right', 'right');
192
193     $params =   array(  0 => $comments,
194                                     1 => array('text' => _('Category'), 'from' => $cat, 'to' => ''),
195                                     2 => array('text' => _('Location'), 'from' => $loc, 'to' => ''));
196
197     $rep = new FrontReport(_('Inventory Planning Report'), $filename, user_pagesize());
198
199     $rep->Font();
200     $rep->Info($params, $cols, $headers, $aligns);
201     $rep->Header();
202
203         $res = getTransactions($category, $location);
204         $catt = '';
205         while ($trans=db_fetch($res))
206         {
207                 if ($catt != $trans['cat_description'])
208                 {
209                         if ($catt != '')
210                         {
211                                 $rep->Line($rep->row - 2);
212                                 $rep->NewLine(2, 3);
213                         }
214                         $rep->TextCol(0, 1, $trans['category_id']);
215                         $rep->TextCol(1, 2, $trans['cat_description']);
216                         $catt = $trans['cat_description'];
217                         $rep->NewLine();
218                 }
219                 if ($location == 'all')
220                         $loc_code = "";
221                 else
222                         $loc_code = $trans['loc_code'];
223                 $custqty = getCustQty($trans['stock_id'], $loc_code);
224                 $custqty += getCustAsmQty($trans['stock_id'], $loc_code);
225                 $suppqty = getSuppQty($trans['stock_id'], $loc_code);
226                 $period = getPeriods($trans['stock_id'], $trans['loc_code']);
227                 $rep->NewLine();
228                 $dec = get_qty_dec($trans['stock_id']);
229                 $rep->TextCol(0, 1, $trans['stock_id']);
230                 $rep->TextCol(1, 2, $trans['description']);
231                 $rep->AmountCol(2, 3, $period['prd0'], $dec);
232                 $rep->AmountCol(3, 4, $period['prd1'], $dec);
233                 $rep->AmountCol(4, 5, $period['prd2'], $dec);
234                 $rep->AmountCol(5, 6, $period['prd3'], $dec);
235                 $rep->AmountCol(6, 7, $period['prd4'], $dec);
236
237                 $MaxMthSales = Max($period['prd0'], $period['prd1'], $period['prd2'], $period['prd3']);
238                 $IdealStockHolding = $MaxMthSales * 3;
239                 $rep->AmountCol(7, 8, $IdealStockHolding, $dec);
240
241                 $rep->AmountCol(8, 9, $trans['qty_on_hand'], $dec);
242                 $rep->AmountCol(9, 10, $custqty, $dec);
243                 $rep->AmountCol(10, 11, $suppqty, $dec);
244
245                 $SuggestedTopUpOrder = $IdealStockHolding - $trans['qty_on_hand'] + $custqty - $suppqty;
246                 if ($SuggestedTopUpOrder < 0.0)
247                         $SuggestedTopUpOrder = 0.0;
248                 $rep->AmountCol(11, 12, $SuggestedTopUpOrder, $dec);
249         }
250         $rep->Line($rep->row - 4);
251         $rep->NewLine();
252     $rep->End();
253 }
254
255 ?>