Bug 5695: Purchase Order Item Description should be saved on the PO line description...
[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         if (!$po_line->descr_editable)
95         {
96                         $data = get_purchase_data($po_obj->supplier_id, $po_line->stock_id);
97                         if ($data !== false && $data['supplier_description'] != "")
98                                 $po_line->item_description = $data['supplier_description'];
99         }
100                 $sql = "INSERT INTO ".TB_PREF."purch_order_details (order_no, item_code, description, delivery_date,    unit_price,     quantity_ordered) VALUES (";
101                 $sql .= $po_obj->order_no . ", " . db_escape($po_line->stock_id). "," .
102                 db_escape($po_line->item_description). ",'" .
103                 date2sql($po_line->req_del_date) . "'," .
104                 db_escape($po_line->price) . ", " .
105                 db_escape($po_line->quantity). ")";
106                 db_query($sql, "One of the purchase order detail records could not be inserted");
107                 $po_obj->line_items[$line_no]->po_detail_rec = db_insert_id();
108      }
109
110         $Refs->save(ST_PURCHORDER, $po_obj->order_no, $po_obj->reference);
111
112         add_audit_trail(ST_PURCHORDER, $po_obj->order_no, $po_obj->orig_order_date);
113         hook_db_postwrite($po_obj, ST_PURCHORDER);
114         commit_transaction();
115
116         return $po_obj->order_no;
117 }
118
119 //----------------------------------------------------------------------------------------
120
121 function update_po(&$po_obj)
122 {
123         begin_transaction();
124         hook_db_prewrite($po_obj, ST_PURCHORDER);
125
126     /*Update the purchase order header with any changes */
127     $sql = "UPDATE ".TB_PREF."purch_orders SET Comments=" . db_escape($po_obj->Comments) . ",
128                 requisition_no= ". db_escape( $po_obj->supp_ref). ",
129                 into_stock_location=" . db_escape($po_obj->Location). ",
130                 ord_date='" . date2sql($po_obj->orig_order_date) . "',
131                 delivery_address=" . db_escape($po_obj->delivery_address).",
132                 total=". db_escape($po_obj->get_trans_total()).",
133                 prep_amount=". db_escape($po_obj->prep_amount).",
134                 tax_included=". db_escape($po_obj->tax_included);
135     $sql .= " WHERE order_no = " . $po_obj->order_no;
136         db_query($sql, "The purchase order could not be updated");
137
138         $sql = "DELETE FROM ".TB_PREF."purch_order_details WHERE order_no="
139                 .db_escape($po_obj->order_no);
140         db_query($sql, "could not delete old purch order details");
141
142     /*Now Update the purchase order detail records */
143     foreach ($po_obj->line_items as $po_line)
144     {
145         if (!$po_line->descr_editable)
146         {
147                         $data = get_purchase_data($po_obj->supplier_id, $po_line->stock_id);
148                         if ($data !== false && $data['supplier_description'] != "")
149                                 $po_line->item_description = $data['supplier_description'];
150         }
151         $sql = "INSERT INTO ".TB_PREF."purch_order_details (po_detail_item, order_no, item_code, 
152                 description, delivery_date, unit_price, quantity_ordered, quantity_received) VALUES ("
153                         .db_escape($po_line->po_detail_rec ? $po_line->po_detail_rec : 0). ","
154                         .$po_obj->order_no . ","
155                         .db_escape($po_line->stock_id). ","
156                         .db_escape($po_line->item_description). ",'"
157                         .date2sql($po_line->req_del_date) . "',"
158                         .db_escape($po_line->price) . ", "
159                         .db_escape($po_line->quantity) . ", "
160                         .db_escape($po_line->qty_received) . ")";
161                 db_query($sql, "One of the purchase order detail records could not be updated");
162     }
163
164         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);
165
166         add_audit_trail($po_obj->trans_type, $po_obj->order_no, Today(), _("Updated."));
167         hook_db_postwrite($po_obj, ST_PURCHORDER);
168         commit_transaction();
169
170         return $po_obj->order_no;
171 }
172
173 //----------------------------------------------------------------------------------------
174
175 function get_po($order_no) {
176     $sql = "SELECT * FROM ".TB_PREF."purch_orders WHERE order_no = ".db_escape($order_no);
177     $result = db_query($sql);
178
179     return db_fetch($result);
180 }
181
182 //----------------------------------------------------------------------------------------
183
184 function read_po_header($order_no, &$order)
185 {
186         $sql = "SELECT po.*, supplier.*, loc.location_name 
187                 FROM ".TB_PREF."purch_orders po,"
188                         .TB_PREF."suppliers supplier,"
189                         .TB_PREF."locations loc
190                 WHERE po.supplier_id = supplier.supplier_id
191                 AND loc.loc_code = into_stock_location
192                 AND po.order_no = ".db_escape($order_no);
193
194         $result = db_query($sql, "The order cannot be retrieved");
195
196         if (db_num_rows($result) == 1)
197         {
198
199         $myrow = db_fetch($result);
200
201         $order->trans_type = ST_PURCHORDER;
202         $order->order_no = $order_no;
203
204         $order->set_supplier($myrow["supplier_id"], $myrow["supp_name"], $myrow["curr_code"],
205                 $myrow['tax_group_id'], $myrow["tax_included"]);
206
207                 $order->credit = get_current_supp_credit($order->supplier_id);
208
209         $order->orig_order_date = sql2date($myrow["ord_date"]);
210         $order->Comments = $myrow["comments"];
211         $order->Location = $myrow["into_stock_location"];
212         $order->supp_ref = $myrow["requisition_no"];
213         $order->reference = $myrow["reference"];
214         $order->delivery_address = $myrow["delivery_address"];
215         $order->alloc = $myrow["alloc"];
216         $order->prep_amount = $myrow["prep_amount"];
217         $order->prepayments = get_payments_for($order_no, ST_PURCHORDER, $myrow["supplier_id"]);
218
219         return true;
220         }
221
222         display_db_error("FATAL : duplicate purchase order found", "", true);
223         return false;
224 }
225
226 //----------------------------------------------------------------------------------------
227
228 function read_po_items($order_no, &$order, $open_items_only=false)
229 {
230         /*now populate the line po array with the purchase order details records */
231
232         $sql = "SELECT poline.*, units, editable
233                 FROM ".TB_PREF."purch_order_details poline
234                         LEFT JOIN ".TB_PREF."stock_master item  ON poline.item_code=item.stock_id
235                 WHERE order_no =".db_escape($order_no);
236
237     if ($open_items_only)
238                 $sql .= " AND (poline.quantity_ordered > poline.quantity_received) ";
239
240         $sql .= " ORDER BY po_detail_item";
241
242         $result = db_query($sql, "The lines on the purchase order cannot be retrieved");
243
244     if (db_num_rows($result) > 0)
245     {
246                 while ($myrow = db_fetch($result))
247         {
248                         $data = get_purchase_data($order->supplier_id, $myrow['item_code']);
249                         if ($data !== false && !$myrow['editable'] && $data['supplier_description'] != "" && 
250                                 $myrow['description'] != $data['supplier_description']) // backward compatibility
251                                 $myrow['description'] = $data['supplier_description'];
252                         if (is_null($myrow["units"]))
253             {
254                         $units = "";
255             }
256             else
257             {
258                 $units = $myrow["units"];
259             }
260
261             if ($order->add_to_order($order->lines_on_order, $myrow["item_code"],
262                 $myrow["quantity_ordered"],$myrow["description"],
263                 $myrow["unit_price"],$units, sql2date($myrow["delivery_date"]),
264                 $myrow["qty_invoiced"], $myrow["quantity_received"])) {
265                                 $order->line_items[$order->lines_on_order-1]->po_detail_rec = $myrow["po_detail_item"];
266                         }
267         } /* line po from purchase order details */
268     } //end of checks on returned data set
269 }
270
271 //----------------------------------------------------------------------------------------
272
273 function read_po($order_no, &$order, $open_items_only=false)
274 {
275         $result = read_po_header($order_no, $order);
276
277         if ($result)
278                 read_po_items($order_no, $order, $open_items_only);
279 }
280
281 //----------------------------------------------------------------------------------------
282
283 function get_po_items($order_no)
284 {
285         $sql = "SELECT item_code, quantity_ordered, quantity_received, qty_invoiced
286                 FROM ".TB_PREF."purch_order_details
287                 WHERE order_no=".db_escape($order_no)
288                 ." ORDER BY po_detail_item";
289
290         $result = db_query($sql, "could not query purch order details");
291     check_db_error("Could not check that the details of the purchase order had not been changed by another user ", $sql);
292     return $result;
293 }
294 //----------------------------------------------------------------------------------------
295
296 function get_short_info($stock_id)
297 {
298         $sql = "SELECT description, units, mb_flag
299                 FROM ".TB_PREF."stock_master WHERE stock_id = ".db_escape($stock_id);
300
301         return db_query($sql,"The stock details for " . $stock_id . " could not be retrieved");
302 }
303
304 function get_sql_for_po_search_completed($from, $to, $supplier_id=ALL_TEXT, $location=ALL_TEXT,
305         $order_number = '', $stock_id = '', $also_closed=false)
306 {
307         $sql = "SELECT 
308                 porder.order_no, 
309                 porder.reference, 
310                 supplier.supp_name, 
311                 location.location_name,
312                 porder.requisition_no, 
313                 porder.ord_date, 
314                 supplier.curr_code, 
315                 Sum(line.unit_price*line.quantity_ordered) AS OrderValue,
316                 Sum(line.delivery_date < '". date2sql(Today()) ."'
317                 AND (line.quantity_ordered > line.quantity_received)) As OverDue,
318                 porder.into_stock_location,
319                 chk.isopen
320                 FROM ".TB_PREF."purch_orders as porder
321                                 LEFT JOIN (
322                                         SELECT order_no, SUM(quantity_ordered-quantity_received + quantity_ordered-qty_invoiced) isopen
323                                         FROM ".TB_PREF."purch_order_details
324                                         GROUP BY order_no
325                                 ) chk ON chk.order_no=porder.order_no,"
326                         .TB_PREF."purch_order_details as line, "
327                         .TB_PREF."suppliers as supplier, "
328                         .TB_PREF."locations as location
329                 WHERE porder.order_no = line.order_no
330                 AND porder.supplier_id = supplier.supplier_id
331                 AND location.loc_code = porder.into_stock_location ";
332
333         if ($supplier_id != ALL_TEXT)
334                 $sql .= "AND supplier.supplier_id=".$supplier_id." ";
335         if ($order_number != "")
336         {
337                 $sql .= "AND porder.reference LIKE ".db_escape('%'. $order_number . '%');
338         }
339         else
340         {
341
342                 $data_after = date2sql($from);
343                 $date_before = date2sql($to);
344
345                 $sql .= " AND porder.ord_date >= '$data_after'";
346                 $sql .= " AND porder.ord_date <= '$date_before'";
347
348                 if ($location != ALL_TEXT)
349                 {
350                         $sql .= " AND porder.into_stock_location = ".db_escape($location);
351                 }
352                 if ($stock_id !== '')
353                 {
354                         $sql .= " AND line.item_code=".db_escape($stock_id);
355                 }
356                 if ($supplier_id != ALL_TEXT)
357                         $sql .= " AND supplier.supplier_id=".db_escape($supplier_id);
358
359         }
360
361         if (!$also_closed)
362                 $sql .= " AND isopen";
363         $sql .= " GROUP BY porder.order_no";
364         return $sql;
365 }
366
367 function get_sql_for_po_search($from, $to, $supplier_id=ALL_TEXT, $location=ALL_TEXT, $order_number='', $stock_id='')
368 {
369         $sql = "SELECT 
370                 porder.order_no, 
371                 porder.reference,
372                 supplier.supp_name, 
373                 location.location_name,
374                 porder.requisition_no, 
375                 porder.ord_date,
376                 supplier.curr_code,
377                 Sum(line.unit_price*line.quantity_ordered) AS OrderValue,
378                 Sum(line.delivery_date < '". date2sql(Today()) ."'
379                 AND (line.quantity_ordered > line.quantity_received)) As OverDue
380                 FROM ".TB_PREF."purch_orders as porder,"
381                         .TB_PREF."purch_order_details as line, "
382                         .TB_PREF."suppliers as supplier, "
383                         .TB_PREF."locations as location
384                 WHERE porder.order_no = line.order_no
385                 AND porder.supplier_id = supplier.supplier_id
386                 AND location.loc_code = porder.into_stock_location
387                 AND (line.quantity_ordered > line.quantity_received) ";
388
389         if ($order_number != "")
390         {
391                 $sql .= "AND porder.reference LIKE ".db_escape('%'. $order_number . '%');
392         }
393         else
394         {
395                 $data_after = date2sql($from);
396                 $data_before = date2sql($to);
397
398                 $sql .= "  AND porder.ord_date >= '$data_after'";
399                 $sql .= "  AND porder.ord_date <= '$data_before'";
400
401                 if ($location != ALL_TEXT)
402                 {
403                         $sql .= " AND porder.into_stock_location = ".db_escape($location);
404                 }
405
406                 if ($stock_id != '')
407                 {
408                         $sql .= " AND line.item_code=".db_escape($stock_id);
409                 }
410                 if ($supplier_id != ALL_TEXT)
411                         $sql .= " AND supplier.supplier_id=".db_escape($supplier_id);
412         } //end not order number selected
413
414         $sql .= " GROUP BY porder.order_no";
415         return $sql;
416 }
417