[0004212] Work Order Entry: fixed error when voided WO refence is reused.
[fa-stable.git] / reporting / rep308.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 = 'SA_ITEMSVALREP';
13 // ----------------------------------------------------------------
14 // $ Revision:  2.4 $
15 // Creator:             boxygen, Joe Hunt
16 // date_:               2017-05-14
17 // Title:               Costed Inventory Movements
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/ui/ui_input.inc");
24 include_once($path_to_root . "/includes/data_checks.inc");
25 include_once($path_to_root . "/gl/includes/gl_db.inc");
26 include_once($path_to_root . "/sales/includes/db/sales_types_db.inc");
27 include_once($path_to_root . "/inventory/includes/inventory_db.inc");
28
29 //----------------------------------------------------------------------------------------------------
30
31 inventory_movements();
32
33 function get_domestic_price($myrow, $stock_id)
34 {
35         if ($myrow['type'] == ST_SUPPRECEIVE || $myrow['type'] == ST_SUPPCREDIT)
36         {
37                 $price = $myrow['price'];
38                 if ($myrow['person_id'] > 0)
39                 {
40                         // Do we have foreign currency?
41                         $supp = get_supplier($myrow['person_id']);
42                         $currency = $supp['curr_code'];
43                         $ex_rate = get_exchange_rate_to_home_currency($currency, sql2date($myrow['tran_date']));
44                         $price /= $ex_rate;
45                 }       
46         }
47         else
48                 $price = $myrow['standard_cost']; // Item Adjustments just have the real cost
49         return $price;
50 }       
51
52 function fetch_items($category=0)
53 {
54                 $sql = "SELECT stock_id, stock.description AS name,
55                                 stock.category_id,units,
56                                 cat.description
57                         FROM ".TB_PREF."stock_master stock LEFT JOIN ".TB_PREF."stock_category cat ON stock.category_id=cat.category_id
58                                 WHERE mb_flag <> 'D' AND mb_flag <> 'F'";
59                 if ($category != 0)
60                         $sql .= " AND cat.category_id = ".db_escape($category);
61                 $sql .= " ORDER BY stock.category_id, stock_id";
62
63     return db_query($sql,"No transactions were returned");
64 }
65
66 function trans_qty($stock_id, $location=null, $from_date, $to_date, $inward = true)
67 {
68         if ($from_date == null)
69                 $from_date = Today();
70
71         $from_date = date2sql($from_date);      
72
73         if ($to_date == null)
74                 $to_date = Today();
75
76         $to_date = date2sql($to_date);
77
78         $sql = "SELECT ".($inward ? '' : '-')."SUM(qty) FROM ".TB_PREF."stock_moves
79                 WHERE stock_id=".db_escape($stock_id)."
80                 AND tran_date >= '$from_date' 
81                 AND tran_date <= '$to_date' AND type <> ".ST_LOCTRANSFER;
82
83         if ($location != '')
84                 $sql .= " AND loc_code = ".db_escape($location);
85
86         if ($inward)
87                 $sql .= " AND qty > 0 ";
88         else
89                 $sql .= " AND qty < 0 ";
90
91         $result = db_query($sql, "QOH calculation failed");
92
93         $myrow = db_fetch_row($result); 
94
95         return $myrow[0];
96
97 }
98
99 function avg_unit_cost($stock_id, $location=null, $to_date)
100 {
101         if ($to_date == null)
102                 $to_date = Today();
103
104         $to_date = date2sql($to_date);
105
106         $sql = "SELECT move.*, IF(ISNULL(supplier.supplier_id), debtor.debtor_no, supplier.supplier_id) person_id
107                 FROM ".TB_PREF."stock_moves move
108                                 LEFT JOIN ".TB_PREF."supp_trans credit ON credit.trans_no=move.trans_no AND credit.type=move.type
109                                 LEFT JOIN ".TB_PREF."grn_batch grn ON grn.id=move.trans_no AND 25=move.type
110                                 LEFT JOIN ".TB_PREF."suppliers supplier ON IFNULL(grn.supplier_id, credit.supplier_id)=supplier.supplier_id
111                                 LEFT JOIN ".TB_PREF."debtor_trans cust_trans ON cust_trans.trans_no=move.trans_no AND cust_trans.type=move.type
112                                 LEFT JOIN ".TB_PREF."debtors_master debtor ON cust_trans.debtor_no=debtor.debtor_no
113                         WHERE stock_id=".db_escape($stock_id)."
114                         AND move.tran_date < '$to_date' AND qty <> 0 AND move.type <> ".ST_LOCTRANSFER;
115
116         if ($location != '')
117                 $sql .= " AND move.loc_code = ".db_escape($location);
118
119         $sql .= " ORDER BY tran_date";  
120
121         $result = db_query($sql, "No standard cost transactions were returned");
122
123     if ($result == false)
124         return 0;
125
126         $qty = $tot_cost = 0;
127         while ($row=db_fetch($result))
128         {
129                 $qty += $row['qty'];    
130                 $price = get_domestic_price($row, $stock_id);
131         $tran_cost = $price * $row['qty'];
132         $tot_cost += $tran_cost;
133         }
134         if ($qty == 0)
135                 return 0;
136         return $tot_cost / $qty;
137 }
138
139 //----------------------------------------------------------------------------------------------------
140
141 function trans_qty_unit_cost($stock_id, $location=null, $from_date, $to_date, $inward = true)
142 {
143         if ($from_date == null)
144                 $from_date = Today();
145
146         $from_date = date2sql($from_date);      
147
148         if ($to_date == null)
149                 $to_date = Today();
150
151         $to_date = date2sql($to_date);
152
153         $sql = "SELECT move.*, IF(ISNULL(supplier.supplier_id), debtor.debtor_no, supplier.supplier_id) person_id
154                 FROM ".TB_PREF."stock_moves move
155                                 LEFT JOIN ".TB_PREF."supp_trans credit ON credit.trans_no=move.trans_no AND credit.type=move.type
156                                 LEFT JOIN ".TB_PREF."grn_batch grn ON grn.id=move.trans_no AND 25=move.type
157                                 LEFT JOIN ".TB_PREF."suppliers supplier ON IFNULL(grn.supplier_id, credit.supplier_id)=supplier.supplier_id
158                                 LEFT JOIN ".TB_PREF."debtor_trans cust_trans ON cust_trans.trans_no=move.trans_no AND cust_trans.type=move.type
159                                 LEFT JOIN ".TB_PREF."debtors_master debtor ON cust_trans.debtor_no=debtor.debtor_no
160                 WHERE stock_id=".db_escape($stock_id)."
161                 AND move.tran_date >= '$from_date' AND move.tran_date <= '$to_date' AND qty <> 0 AND move.type <> ".ST_LOCTRANSFER;
162
163         if ($location != '')
164                 $sql .= " AND move.loc_code = ".db_escape($location);
165
166         if ($inward)
167                 $sql .= " AND qty > 0 ";
168         else
169                 $sql .= " AND qty < 0 ";
170         $sql .= " ORDER BY tran_date";
171         
172         $result = db_query($sql, "No standard cost transactions were returned");
173     
174     if ($result == false)
175         return 0;
176         
177         $qty = $tot_cost = 0;
178         while ($row=db_fetch($result))
179         {
180         $qty += $row['qty'];
181         $price = get_domestic_price($row, $stock_id); 
182         $tran_cost = $row['qty'] * $price;
183         $tot_cost += $tran_cost;
184         }       
185         if ($qty == 0)
186                 return 0;
187         return $tot_cost / $qty;
188 }
189
190 //----------------------------------------------------------------------------------------------------
191
192 function inventory_movements()
193 {
194     global $path_to_root;
195
196     $from_date = $_POST['PARAM_0'];
197     $to_date = $_POST['PARAM_1'];
198     $category = $_POST['PARAM_2'];
199         $location = $_POST['PARAM_3'];
200     $comments = $_POST['PARAM_4'];
201         $orientation = $_POST['PARAM_5'];
202         $destination = $_POST['PARAM_6'];
203         if ($destination)
204                 include_once($path_to_root . "/reporting/includes/excel_report.inc");
205         else
206                 include_once($path_to_root . "/reporting/includes/pdf_report.inc");
207
208         $orientation = ($orientation ? 'L' : 'P');
209         if ($category == ALL_NUMERIC)
210                 $category = 0;
211         if ($category == 0)
212                 $cat = _('All');
213         else
214                 $cat = get_category_name($category);
215
216         if ($location == '')
217                 $loc = _('All');
218         else
219                 $loc = get_location_name($location);
220
221         $cols = array(0, 60, 134, 160, 185, 215, 250, 275, 305, 340, 365, 395, 430, 455, 485, 520);
222
223         $headers = array(_('Category'), _('Description'),       _('UOM'), '', '', _('OpeningStock'), '', '',_('StockIn'), '', '', _('Delivery'), '', '', _('ClosingStock'));
224         $headers2 = array("", "", "", _("QTY"), _("Rate"), _("Value"), _("QTY"), _("Rate"), _("Value"), _("QTY"), _("Rate"), _("Value"), _("QTY"), _("Rate"), _("Value"));
225
226         $aligns = array('left', 'left', 'left', 'right', 'right', 'right', 'right','right' ,'right', 'right', 'right','right', 'right', 'right', 'right');
227
228     $params =   array(  0 => $comments,
229                                                 1 => array('text' => _('Period'), 'from' => $from_date, 'to' => $to_date),
230                                     2 => array('text' => _('Category'), 'from' => $cat, 'to' => ''),
231                                                 3 => array('text' => _('Location'), 'from' => $loc, 'to' => ''));
232
233     $rep = new FrontReport(_('Costed Inventory Movements'), "CostedInventoryMovements", user_pagesize(), 8, $orientation);
234     if ($orientation == 'L')
235         recalculate_cols($cols);
236
237     $rep->Font();
238     $rep->Info($params, $cols, $headers2, $aligns, $cols, $headers, $aligns);
239     $rep->NewPage();
240
241         $totval_open = $totval_in = $totval_out = $totval_close = 0; 
242         $result = fetch_items($category);
243
244         $dec = user_price_dec();
245         $catgor = '';
246         while ($myrow=db_fetch($result))
247         {
248                 if ($catgor != $myrow['description'])
249                 {
250                         $rep->NewLine(2);
251                         $rep->fontSize += 2;
252                         $rep->TextCol(0, 3, $myrow['category_id'] . " - " . $myrow['description']);
253                         $catgor = $myrow['description'];
254                         $rep->fontSize -= 2;
255                         $rep->NewLine();
256                 }
257                 $qoh_start = get_qoh_on_date($myrow['stock_id'], $location, add_days($from_date, -1));
258                 $qoh_end = get_qoh_on_date($myrow['stock_id'], $location, $to_date);
259                 
260                 $inward = trans_qty($myrow['stock_id'], $location, $from_date, $to_date);
261                 $outward = trans_qty($myrow['stock_id'], $location, $from_date, $to_date, false);
262                 $openCost = avg_unit_cost($myrow['stock_id'], $location, $from_date);
263                 $unitCost = avg_unit_cost($myrow['stock_id'], $location, add_days($to_date, 1));
264                 if ($qoh_start == 0 && $inward == 0 && $outward == 0 && $qoh_end == 0)
265                         continue;
266                 $rep->NewLine();
267                 $rep->TextCol(0, 1,     $myrow['stock_id']);
268                 $rep->TextCol(1, 2, substr($myrow['name'], 0, 24) . ' ');
269                 $rep->TextCol(2, 3, $myrow['units']);
270                 $rep->AmountCol(3, 4, $qoh_start, get_qty_dec($myrow['stock_id']));
271                 $rep->AmountCol(4, 5, $openCost, $dec);
272                 $openCost *= $qoh_start;
273                 $totval_open += $openCost;
274                 $rep->AmountCol(5, 6, $openCost);
275                 
276                 if($inward>0){
277                         $rep->AmountCol(6, 7, $inward, get_qty_dec($myrow['stock_id']));
278                         $unitCost_in = trans_qty_unit_cost($myrow['stock_id'], $location, $from_date, $to_date);
279                         $rep->AmountCol(7, 8, $unitCost_in,$dec);
280                         $unitCost_in *= $inward;
281                         $totval_in += $unitCost_in;
282                         $rep->AmountCol(8, 9, $unitCost_in);
283                 }
284                 
285                 if($outward>0){
286                         $rep->AmountCol(9, 10, $outward, get_qty_dec($myrow['stock_id']));
287                         $unitCost_out = trans_qty_unit_cost($myrow['stock_id'], $location, $from_date, $to_date, false);
288                         $rep->AmountCol(10, 11, $unitCost_out,$dec);
289                         $unitCost_out *= $outward;
290                         $totval_out += $unitCost_out;
291                         $rep->AmountCol(11, 12, $unitCost_out);
292                 }
293                 
294                 $rep->AmountCol(12, 13, $qoh_end, get_qty_dec($myrow['stock_id']));
295                 $rep->AmountCol(13, 14, $unitCost,$dec);
296                 $unitCost *= $qoh_end;
297                 $totval_close += $unitCost;
298                 $rep->AmountCol(14, 15, $unitCost);
299                 
300                 $rep->NewLine(0, 1);
301         }
302         $rep->Line($rep->row  - 4);
303         $rep->NewLine(2);
304         $rep->TextCol(0, 1,     _("Total Movement"));
305         $rep->AmountCol(5, 6, $totval_open);
306         $rep->AmountCol(8, 9, $totval_in);
307         $rep->AmountCol(11, 12, $totval_out);
308         $rep->AmountCol(14, 15, $totval_open + $totval_in - $totval_out);
309         $rep->NewLine(1);
310         $rep->TextCol(0, 1,     _("Total Out"));
311         $rep->AmountCol(14, 15, $totval_close);
312         $rep->Line($rep->row  - 4);
313
314     $rep->End();
315 }
316