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