23f19a09f582b81b56c8b63ca2df6244ac19a60c
[fa-stable.git] / purchasing / includes / db / po_db.inc
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 // ------------------------------------------------------------------------------
13
14 function get_supplier_details_to_order(&$order, $supplier_id)
15 {
16         $sql = "SELECT curr_code, supp_name, tax_group_id, supp.tax_included, dimension_id, dimension2_id,
17                         supp.credit_limit - Sum((ov_amount + ov_gst + ov_discount)) as cur_credit,
18                                 terms.terms, terms.days_before_due, terms.day_in_following_month
19                 FROM ".TB_PREF."suppliers supp
20                          LEFT JOIN ".TB_PREF."supp_trans trans ON supp.supplier_id = trans.supplier_id
21                          LEFT JOIN ".TB_PREF."payment_terms terms ON supp.payment_terms=terms.terms_indicator
22                 WHERE supp.supplier_id = ".db_escape($supplier_id)."
23                 GROUP BY
24                           supp.supp_name";
25
26         $result = db_query($sql, "The supplier details could not be retreived");
27         $myrow = db_fetch($result);
28
29         $order->credit = $myrow["cur_credit"];
30         $order->terms = array( 
31                 'description' => $myrow['terms'],
32                 'days_before_due' => $myrow['days_before_due'], 
33                 'day_in_following_month' => $myrow['day_in_following_month'] );
34
35         $_POST['supplier_id'] = $supplier_id;
36         $_POST['supplier_name'] = $myrow["supp_name"];
37         $_POST['curr_code'] = $myrow["curr_code"];
38         $_POST['dimension'] = $myrow["dimension_id"];
39         $_POST['dimension2'] = $myrow["dimension2_id"];
40
41         $order->set_supplier($supplier_id, $myrow["supp_name"], $myrow["curr_code"], 
42                 $myrow["tax_group_id"], $myrow["tax_included"]);
43 }
44
45 //----------------------------------------------------------------------------------------
46
47 function delete_po($po)
48 {
49         global $Refs;
50
51         begin_transaction();
52         hook_db_prevoid(ST_PURCHORDER, $po);
53         $sql = "DELETE FROM ".TB_PREF."purch_orders WHERE order_no=".db_escape($po);
54         db_query($sql, "The order header could not be deleted");
55
56         $sql = "DELETE FROM ".TB_PREF."purch_order_details WHERE order_no =".db_escape($po);
57         db_query($sql, "The order detail lines could not be deleted");
58
59         $Refs->restore_last(ST_PURCHORDER, $po);
60         commit_transaction();
61 }
62
63 //----------------------------------------------------------------------------------------
64
65 function add_po(&$po_obj)
66 {
67         global $Refs;
68
69         begin_transaction();
70         hook_db_prewrite($po_obj, ST_PURCHORDER);
71
72      /*Insert to purchase order header record */
73      $sql = "INSERT INTO ".TB_PREF."purch_orders (supplier_id, Comments, ord_date, reference, 
74         requisition_no, into_stock_location, delivery_address, total, tax_included, prep_amount) VALUES(";
75      $sql .= db_escape($po_obj->supplier_id) . "," .
76          db_escape($po_obj->Comments) . ",'" .
77          date2sql($po_obj->orig_order_date) . "', " .
78                  db_escape($po_obj->reference) . ", " .
79          db_escape($po_obj->supp_ref) . ", " .
80          db_escape($po_obj->Location) . ", " .
81          db_escape($po_obj->delivery_address) . ", " .
82          db_escape($po_obj->get_trans_total()). ", " .
83          db_escape($po_obj->tax_included). ", " .
84          db_escape($po_obj->prep_amount). ")";
85
86         db_query($sql, "The purchase order header record could not be inserted");
87
88      /*Get the auto increment value of the order number created from the sql above */
89      $po_obj->order_no = db_insert_id();
90
91      /*Insert the purchase order detail records */
92      foreach ($po_obj->line_items as $line_no => $po_line)
93      {
94                 $sql = "INSERT INTO ".TB_PREF."purch_order_details (order_no, item_code, description, delivery_date,    unit_price,     quantity_ordered) VALUES (";
95                 $sql .= $po_obj->order_no . ", " . db_escape($po_line->stock_id). "," .
96                 db_escape($po_line->item_description). ",'" .
97                 date2sql($po_line->req_del_date) . "'," .
98                 db_escape($po_line->price) . ", " .
99                 db_escape($po_line->quantity). ")";
100                 db_query($sql, "One of the purchase order detail records could not be inserted");
101                 $po_obj->line_items[$line_no]->po_detail_rec = db_insert_id();
102      }
103
104         $Refs->save(ST_PURCHORDER, $po_obj->order_no, $po_obj->reference);
105
106         add_audit_trail(ST_PURCHORDER, $po_obj->order_no, $po_obj->orig_order_date);
107         hook_db_postwrite($po_obj, ST_PURCHORDER);
108         commit_transaction();
109
110         return $po_obj->order_no;
111 }
112
113 //----------------------------------------------------------------------------------------
114
115 function update_po(&$po_obj)
116 {
117         begin_transaction();
118         hook_db_prewrite($po_obj, ST_PURCHORDER);
119
120     /*Update the purchase order header with any changes */
121     $sql = "UPDATE ".TB_PREF."purch_orders SET Comments=" . db_escape($po_obj->Comments) . ",
122                 requisition_no= ". db_escape( $po_obj->supp_ref). ",
123                 into_stock_location=" . db_escape($po_obj->Location). ",
124                 ord_date='" . date2sql($po_obj->orig_order_date) . "',
125                 delivery_address=" . db_escape($po_obj->delivery_address).",
126                 total=". db_escape($po_obj->get_trans_total()).",
127                 prep_amount=". db_escape($po_obj->prep_amount).",
128                 tax_included=". db_escape($po_obj->tax_included);
129     $sql .= " WHERE order_no = " . $po_obj->order_no;
130         db_query($sql, "The purchase order could not be updated");
131
132         $sql = "DELETE FROM ".TB_PREF."purch_order_details WHERE order_no="
133                 .db_escape($po_obj->order_no);
134         db_query($sql, "could not delete old purch order details");
135
136     /*Now Update the purchase order detail records */
137     foreach ($po_obj->line_items as $po_line)
138     {
139         $sql = "INSERT INTO ".TB_PREF."purch_order_details (po_detail_item, order_no, item_code, 
140                 description, delivery_date, unit_price, quantity_ordered, quantity_received) VALUES ("
141                         .db_escape($po_line->po_detail_rec ? $po_line->po_detail_rec : 0). ","
142                         .$po_obj->order_no . ","
143                         .db_escape($po_line->stock_id). ","
144                         .db_escape($po_line->item_description). ",'"
145                         .date2sql($po_line->req_del_date) . "',"
146                         .db_escape($po_line->price) . ", "
147                         .db_escape($po_line->quantity) . ", "
148                         .db_escape($po_line->qty_received) . ")";
149                 db_query($sql, "One of the purchase order detail records could not be updated");
150     }
151
152         reallocate_payments($po_obj->order_no, ST_PURCHORDER, $po_obj->orig_order_date, $po_obj->get_trans_total(), $po_obj->prepayments, $po_obj->supplier_id);
153
154         add_audit_trail($po_obj->trans_type, $po_obj->order_no, Today(), _("Updated."));
155         hook_db_postwrite($po_obj, ST_PURCHORDER);
156         commit_transaction();
157
158         return $po_obj->order_no;
159 }
160
161 //----------------------------------------------------------------------------------------
162
163 function get_po($order_no) {
164     $sql = "SELECT * FROM ".TB_PREF."purch_orders WHERE order_no = ".db_escape($order_no);
165     $result = db_query($sql);
166
167     return db_fetch($result);
168 }
169
170 //----------------------------------------------------------------------------------------
171
172 function read_po_header($order_no, &$order)
173 {
174         $sql = "SELECT po.*, supplier.*, loc.location_name 
175                 FROM ".TB_PREF."purch_orders po,"
176                         .TB_PREF."suppliers supplier,"
177                         .TB_PREF."locations loc
178                 WHERE po.supplier_id = supplier.supplier_id
179                 AND loc.loc_code = into_stock_location
180                 AND po.order_no = ".db_escape($order_no);
181
182         $result = db_query($sql, "The order cannot be retrieved");
183
184         if (db_num_rows($result) == 1)
185         {
186
187         $myrow = db_fetch($result);
188
189         $order->trans_type = ST_PURCHORDER;
190         $order->order_no = $order_no;
191
192         $order->set_supplier($myrow["supplier_id"], $myrow["supp_name"], $myrow["curr_code"],
193                 $myrow['tax_group_id'], $myrow["tax_included"]);
194
195                 $order->credit = get_current_supp_credit($order->supplier_id);
196
197         $order->orig_order_date = sql2date($myrow["ord_date"]);
198         $order->Comments = $myrow["comments"];
199         $order->Location = $myrow["into_stock_location"];
200         $order->supp_ref = $myrow["requisition_no"];
201         $order->reference = $myrow["reference"];
202         $order->delivery_address = $myrow["delivery_address"];
203         $order->alloc = $myrow["alloc"];
204         $order->prep_amount = $myrow["prep_amount"];
205         $order->prepayments = get_payments_for($order_no, ST_PURCHORDER, $myrow["supplier_id"]);
206
207         return true;
208         }
209
210         display_db_error("FATAL : duplicate purchase order found", "", true);
211         return false;
212 }
213
214 //----------------------------------------------------------------------------------------
215
216 function read_po_items($order_no, &$order, $open_items_only=false)
217 {
218         /*now populate the line po array with the purchase order details records */
219
220         $sql = "SELECT poline.*, units
221                 FROM ".TB_PREF."purch_order_details poline
222                         LEFT JOIN ".TB_PREF."stock_master item  ON poline.item_code=item.stock_id
223                 WHERE order_no =".db_escape($order_no);
224
225     if ($open_items_only)
226                 $sql .= " AND (poline.quantity_ordered > poline.quantity_received) ";
227
228         $sql .= " ORDER BY po_detail_item";
229
230         $result = db_query($sql, "The lines on the purchase order cannot be retrieved");
231
232     if (db_num_rows($result) > 0)
233     {
234                 while ($myrow = db_fetch($result))
235         {
236                 $data = get_purchase_data($order->supplier_id, $myrow['item_code']);
237                 if ($data !== false)
238                 {
239                         if ($data['supplier_description'] != "")
240                                 $myrow['description'] = $data['supplier_description'];
241                 }               
242             if (is_null($myrow["units"]))
243             {
244                         $units = "";
245             }
246             else
247             {
248                 $units = $myrow["units"];
249             }
250
251             if ($order->add_to_order($order->lines_on_order, $myrow["item_code"],
252                 $myrow["quantity_ordered"],$myrow["description"],
253                 $myrow["unit_price"],$units, sql2date($myrow["delivery_date"]),
254                 $myrow["qty_invoiced"], $myrow["quantity_received"])) {
255                                 $order->line_items[$order->lines_on_order-1]->po_detail_rec = $myrow["po_detail_item"];
256                         }
257         } /* line po from purchase order details */
258     } //end of checks on returned data set
259 }
260
261 //----------------------------------------------------------------------------------------
262
263 function read_po($order_no, &$order, $open_items_only=false)
264 {
265         $result = read_po_header($order_no, $order);
266
267         if ($result)
268                 read_po_items($order_no, $order, $open_items_only);
269 }
270
271 //----------------------------------------------------------------------------------------
272
273 function get_po_items($order_no)
274 {
275         $sql = "SELECT item_code, quantity_ordered, quantity_received, qty_invoiced
276                 FROM ".TB_PREF."purch_order_details
277                 WHERE order_no=".db_escape($order_no)
278                 ." ORDER BY po_detail_item";
279
280         $result = db_query($sql, "could not query purch order details");
281     check_db_error("Could not check that the details of the purchase order had not been changed by another user ", $sql);
282     return $result;
283 }
284 //----------------------------------------------------------------------------------------
285
286 function get_short_info($stock_id)
287 {
288         $sql = "SELECT description, units, mb_flag
289                 FROM ".TB_PREF."stock_master WHERE stock_id = ".db_escape($stock_id);
290
291         return db_query($sql,"The stock details for " . $stock_id . " could not be retrieved");
292 }
293
294 function get_sql_for_po_search_completed($from, $to, $supplier_id=ALL_TEXT, $location=ALL_TEXT,
295         $order_number = '', $stock_id = '', $also_closed=false)
296 {
297         $sql = "SELECT 
298                 porder.order_no, 
299                 porder.reference, 
300                 supplier.supp_name, 
301                 location.location_name,
302                 porder.requisition_no, 
303                 porder.ord_date, 
304                 supplier.curr_code, 
305                 Sum(line.unit_price*line.quantity_ordered) AS OrderValue,
306                 Sum(line.delivery_date < '". date2sql(Today()) ."'
307                 AND (line.quantity_ordered > line.quantity_received)) As OverDue,
308                 porder.into_stock_location,
309                 chk.isopen
310                 FROM ".TB_PREF."purch_orders as porder
311                                 LEFT JOIN (
312                                         SELECT order_no, SUM(quantity_ordered-quantity_received + quantity_ordered-qty_invoiced) isopen
313                                         FROM ".TB_PREF."purch_order_details
314                                         GROUP BY order_no
315                                 ) chk ON chk.order_no=porder.order_no,"
316                         .TB_PREF."purch_order_details as line, "
317                         .TB_PREF."suppliers as supplier, "
318                         .TB_PREF."locations as location
319                 WHERE porder.order_no = line.order_no
320                 AND porder.supplier_id = supplier.supplier_id
321                 AND location.loc_code = porder.into_stock_location ";
322
323         if ($supplier_id != ALL_TEXT)
324                 $sql .= "AND supplier.supplier_id=".$supplier_id." ";
325         if ($order_number != "")
326         {
327                 $sql .= "AND porder.reference LIKE ".db_escape('%'. $order_number . '%');
328         }
329         else
330         {
331
332                 $data_after = date2sql($from);
333                 $date_before = date2sql($to);
334
335                 $sql .= " AND porder.ord_date >= '$data_after'";
336                 $sql .= " AND porder.ord_date <= '$date_before'";
337
338                 if ($location != ALL_TEXT)
339                 {
340                         $sql .= " AND porder.into_stock_location = ".db_escape($location);
341                 }
342                 if ($stock_id !== '')
343                 {
344                         $sql .= " AND line.item_code=".db_escape($stock_id);
345                 }
346                 if ($supplier_id != ALL_TEXT)
347                         $sql .= " AND supplier.supplier_id=".db_escape($supplier_id);
348
349         }
350
351         if (!$also_closed)
352                 $sql .= " AND isopen";
353         $sql .= " GROUP BY porder.order_no";
354         return $sql;
355 }
356
357 function get_sql_for_po_search($from, $to, $supplier_id=ALL_TEXT, $location=ALL_TEXT, $order_number='', $stock_id='')
358 {
359         $sql = "SELECT 
360                 porder.order_no, 
361                 porder.reference,
362                 supplier.supp_name, 
363                 location.location_name,
364                 porder.requisition_no, 
365                 porder.ord_date,
366                 supplier.curr_code,
367                 Sum(line.unit_price*line.quantity_ordered) AS OrderValue,
368                 Sum(line.delivery_date < '". date2sql(Today()) ."'
369                 AND (line.quantity_ordered > line.quantity_received)) As OverDue
370                 FROM ".TB_PREF."purch_orders as porder,"
371                         .TB_PREF."purch_order_details as line, "
372                         .TB_PREF."suppliers as supplier, "
373                         .TB_PREF."locations as location
374                 WHERE porder.order_no = line.order_no
375                 AND porder.supplier_id = supplier.supplier_id
376                 AND location.loc_code = porder.into_stock_location
377                 AND (line.quantity_ordered > line.quantity_received) ";
378
379         if ($order_number != "")
380         {
381                 $sql .= "AND porder.reference LIKE ".db_escape('%'. $order_number . '%');
382         }
383         else
384         {
385                 $data_after = date2sql($from);
386                 $data_before = date2sql($to);
387
388                 $sql .= "  AND porder.ord_date >= '$data_after'";
389                 $sql .= "  AND porder.ord_date <= '$data_before'";
390
391                 if ($location != ALL_TEXT)
392                 {
393                         $sql .= " AND porder.into_stock_location = ".db_escape($location);
394                 }
395
396                 if ($stock_id != '')
397                 {
398                         $sql .= " AND line.item_code=".db_escape($stock_id);
399                 }
400                 if ($supplier_id != ALL_TEXT)
401                         $sql .= " AND supplier.supplier_id=".db_escape($supplier_id);
402         } //end not order number selected
403
404         $sql .= " GROUP BY porder.order_no";
405         return $sql;
406 }
407