Merged changes from stable branch up to 2.3.12
[fa-stable.git] / admin / db / fiscalyears_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 // fiscal year routines
14 function add_fiscalyear($from_date, $to_date, $closed)
15 {
16         $from = date2sql($from_date);
17         $to = date2sql($to_date);
18
19         $sql = "INSERT INTO ".TB_PREF."fiscal_year (begin, end, closed)
20                 VALUES (".db_escape($from).",".db_escape($to).", ".db_escape($closed).")";
21
22         db_query($sql, "could not add fiscal year");
23 }
24
25 function update_fiscalyear($id, $closed)
26 {
27         $sql = "UPDATE ".TB_PREF."fiscal_year SET closed=".db_escape($closed)."
28                 WHERE id=".db_escape($id);
29
30         db_query($sql, "could not update fiscal year");
31 }
32
33 function get_all_fiscalyears()
34 {
35         $sql = "SELECT * FROM ".TB_PREF."fiscal_year ORDER BY begin";
36
37         return db_query($sql, "could not get all fiscal years");
38 }
39
40 function get_fiscalyear($id)
41 {
42         $sql = "SELECT * FROM ".TB_PREF."fiscal_year WHERE id=".db_escape($id);
43
44         $result = db_query($sql, "could not get fiscal year");
45
46         return db_fetch($result);
47 }
48
49 function get_current_fiscalyear()
50 {
51         global $path_to_root;
52         include_once($path_to_root . "/admin/db/company_db.inc");
53         $year = get_company_pref('f_year');
54
55         $sql = "SELECT * FROM ".TB_PREF."fiscal_year WHERE id=".db_escape($year);
56
57         $result = db_query($sql, "could not get current fiscal year");
58
59         return db_fetch($result);
60 }
61
62
63 function delete_fiscalyear($id)
64 {
65         begin_transaction();
66
67         $sql="DELETE FROM ".TB_PREF."fiscal_year WHERE id=".db_escape($id);
68
69         db_query($sql, "could not delete fiscal year");
70
71         commit_transaction();
72 }
73
74 function is_date_in_fiscalyears($date, $closed=true)
75 {
76         $date = date2sql($date);
77         $sql = "SELECT * FROM ".TB_PREF."fiscal_year WHERE '$date' >= begin AND '$date' <= end";
78         if (!$closed)
79                 $sql .= " AND closed=0";
80         $result = db_query($sql, "could not get all fiscal years");
81         return db_fetch($result) !== false;
82 }
83
84 function get_fiscalyear_begin_for_date($date)
85 {
86         $date = date2sql($date);
87         $sql = "SELECT begin FROM ".TB_PREF."fiscal_year WHERE '$date' >= begin AND '$date' <= end";
88         $result = db_query($sql, "could not get begin date of the fiscal year");
89         $row = db_fetch_row($result);
90         if ($row != false)
91                 return sql2date($row[0]);
92         else
93                 return begin_fiscalyear();
94 }
95
96 function check_begin_end_date($date1, $date2)
97 {
98         $sql = "SELECT MAX(end), MIN(begin) FROM ".TB_PREF."fiscal_year";
99         $result = db_query($sql, "could not retrieve last fiscal years");
100         $row = db_fetch_row($result);
101         if ($row[0] === null)
102                 return true;
103         $max = add_days(sql2date($row[0]), 1);
104         $min = add_days(sql2date($row[1]), -1);
105         return ($max === $date1 || $min === $date2);
106 }
107
108 function next_begin_date()
109 {
110         $sql = "SELECT MAX(end) FROM ".TB_PREF."fiscal_year";
111         $result = db_query($sql, "could not retrieve last fiscal years");
112         $row = db_fetch_row($result);
113         if ($row[0] === null)
114                 return false;
115         return add_days(sql2date($row[0]), 1);
116 }
117
118 function check_years_before($date, $closed=false)
119 {
120         $date = date2sql($date);
121         $sql = "SELECT COUNT(*) FROM ".TB_PREF."fiscal_year WHERE begin < '$date'";
122         if (!$closed)
123                 $sql .= " AND closed=0";
124
125         $result = db_query($sql, "could not check fiscal years before");
126         $row = db_fetch_row($result);
127         return ($row[0] > 0);
128 }
129
130 //---------------------------------------------------------------------------------------------
131 function close_year($year)
132 {
133         $co = get_company_prefs();
134         if (get_gl_account($co['retained_earnings_act']) == false || get_gl_account($co['profit_loss_year_act']) == false)
135         {
136                 display_error(_("The Retained Earnings Account or the Profit and Loss Year Account has not been set in System and General GL Setup"));
137                 return false;
138         }
139         if (!is_account_balancesheet($co['retained_earnings_act']) || is_account_balancesheet($co['profit_loss_year_act']))
140         {
141                 display_error(_("The Retained Earnings Account should be a Balance Account or the Profit and Loss Year Account should be an Expense Account (preferred the last one in the Expense Class)"));
142                 return false;
143         }
144
145         begin_transaction();
146
147         $myrow = get_fiscalyear($year);
148         $to = $myrow['end'];
149         // retrieve total balances from balance sheet accounts
150     $sql = "SELECT SUM(amount) FROM ".TB_PREF."gl_trans INNER JOIN ".TB_PREF."chart_master ON account=account_code
151         INNER JOIN ".TB_PREF."chart_types ON account_type=id INNER JOIN ".TB_PREF."chart_class ON class_id=cid 
152                 WHERE ctype>=".CL_ASSETS." AND ctype <=".CL_EQUITY." AND tran_date <= '$to'";
153         $result = db_query($sql, "The total balance could not be calculated");
154
155         $row = db_fetch_row($result);
156         $balance = round2($row[0], user_price_dec());
157
158         $to = sql2date($to);
159
160         if ($balance != 0.0)
161         {
162                 $trans_type = ST_JOURNAL;
163                 $trans_id = get_next_trans_no($trans_type);
164
165                 add_gl_trans($trans_type, $trans_id, $to, $co['retained_earnings_act'],
166                         0, 0, _("Closing Year"), -$balance);
167                 add_gl_trans($trans_type, $trans_id, $to, $co['profit_loss_year_act'],
168                         0, 0, _("Closing Year"), $balance);
169
170         }       
171         close_transactions($to);
172
173         commit_transaction();
174         return true;
175 }
176
177 function open_year($year)
178 {
179         $myrow = get_fiscalyear($year);
180         $from = sql2date($myrow['begin']);
181
182         begin_transaction();
183         close_transactions(add_days($from, -1));
184         commit_transaction();
185 }
186
187 //---------------------------------------------------------------------------------------------
188 function delete_attachments_and_comments($type_no, $trans_no)
189 {
190         
191         $sql = "SELECT * FROM ".TB_PREF."attachments WHERE type_no = $type_no AND trans_no = $trans_no";
192         $result = db_query($sql, "Could not retrieve attachments");
193         while ($row = db_fetch($result))
194         {
195                 $dir =  company_path(). "/attachments";
196                 if (file_exists($dir."/".$row['unique_name']))
197                         unlink($dir."/".$row['unique_name']);
198                 $sql = "DELETE FROM ".TB_PREF."attachments WHERE  type_no = $type_no AND trans_no = $trans_no";
199                 db_query($sql, "Could not delete attachment");
200         }       
201         $sql = "DELETE FROM ".TB_PREF."comments WHERE  type = $type_no AND id = $trans_no";
202         db_query($sql, "Could not delete comments");
203         $sql = "DELETE FROM ".TB_PREF."refs WHERE  type = $type_no AND id = $trans_no";
204         db_query($sql, "Could not delete refs");
205 }       
206
207 //---------------------------------------------------------------------------------------------
208 function delete_this_fiscalyear($selected_id)
209 {
210         global $db_connections;
211         
212         db_backup($db_connections[$_SESSION["wa_current_user"]->company], 'Security backup before Fiscal Year Removal');
213         begin_transaction();
214         $ref = _("Open Balance");
215         $myrow = get_fiscalyear($selected_id);
216         $to = $myrow['end'];
217         $sql = "SELECT order_no, trans_type FROM ".TB_PREF."sales_orders WHERE ord_date <= '$to' AND type <> 1"; // don't take the templates
218         $result = db_query($sql, "Could not retrieve sales orders");
219         while ($row = db_fetch($result))
220         {
221                 $sql = "SELECT SUM(qty_sent), SUM(quantity) FROM ".TB_PREF."sales_order_details WHERE order_no = {$row['order_no']} AND trans_type = {$row['trans_type']}";
222                 $res = db_query($sql, "Could not retrieve sales order details");
223                 $row2 = db_fetch_row($res);
224                 if ($row2[0] == $row2[1])
225                 {
226                         $sql = "DELETE FROM ".TB_PREF."sales_order_details WHERE order_no = {$row['order_no']} AND trans_type = {$row['trans_type']}";
227                         db_query($sql, "Could not delete sales order details");
228                         $sql = "DELETE FROM ".TB_PREF."sales_orders WHERE order_no = {$row['order_no']} AND trans_type = {$row['trans_type']}";
229                         db_query($sql, "Could not delete sales order");
230                         delete_attachments_and_comments($row['trans_type'], $row['order_no']);
231                 }
232         }
233         $sql = "SELECT order_no FROM ".TB_PREF."purch_orders WHERE ord_date <= '$to'";
234         $result = db_query($sql, "Could not retrieve purchase orders");
235         while ($row = db_fetch($result))
236         {
237                 $sql = "SELECT SUM(quantity_ordered), SUM(quantity_received) FROM ".TB_PREF."purch_order_details WHERE order_no = {$row['order_no']}";
238                 $res = db_query($sql, "Could not retrieve purchase order details");
239                 $row2 = db_fetch_row($res);
240                 if ($row2[0] == $row2[1])
241                 {
242                         $sql = "DELETE FROM ".TB_PREF."purch_order_details WHERE order_no = {$row['order_no']}";
243                         db_query($sql, "Could not delete purchase order details");
244                         $sql = "DELETE FROM ".TB_PREF."purch_orders WHERE order_no = {$row['order_no']}";
245                         db_query($sql, "Could not delete purchase order");
246                         delete_attachments_and_comments(ST_PURCHORDER, $row['order_no']);
247                 }
248         }
249         $sql = "SELECT id FROM ".TB_PREF."grn_batch WHERE delivery_date <= '$to'";
250         $result = db_query($sql, "Could not retrieve grn batch");
251         while ($row = db_fetch($result))
252         {
253                 $sql = "DELETE FROM ".TB_PREF."grn_items WHERE grn_batch_id = {$row['id']}";
254                 db_query($sql, "Could not delete grn items");
255                 $sql = "DELETE FROM ".TB_PREF."grn_batch WHERE id = {$row['id']}";
256                 db_query($sql, "Could not delete grn batch");
257                 delete_attachments_and_comments(25, $row['id']);
258         }
259         $sql = "SELECT trans_no, type FROM ".TB_PREF."debtor_trans WHERE tran_date <= '$to' AND 
260                 (ov_amount + ov_gst + ov_freight + ov_freight_tax + ov_discount) = alloc";
261         $result = db_query($sql, "Could not retrieve debtor trans");
262         while ($row = db_fetch($result))
263         {
264                 if ($row['type'] == ST_SALESINVOICE)
265                 {
266                         $deliveries = get_sales_parent_numbers($row['type'], $row['trans_no']);
267                         foreach ($deliveries as $delivery)
268                         {
269                                 $sql = "DELETE FROM ".TB_PREF."debtor_trans_details WHERE debtor_trans_no = $delivery AND debtor_trans_type = ".ST_CUSTDELIVERY;
270                                 db_query($sql, "Could not delete debtor trans details");
271                                 $sql = "DELETE FROM ".TB_PREF."debtor_trans WHERE trans_no = $delivery AND type = ".ST_CUSTDELIVERY;
272                                 db_query($sql, "Could not delete debtor trans");
273                                 delete_attachments_and_comments(ST_CUSTDELIVERY, $delivery);
274                         }               
275                 }       
276                 $sql = "DELETE FROM ".TB_PREF."cust_allocations WHERE trans_no_from = {$row['trans_no']} AND trans_type_from = {$row['type']}";
277                 db_query($sql, "Could not delete cust allocations");
278                 $sql = "DELETE FROM ".TB_PREF."debtor_trans_details WHERE debtor_trans_no = {$row['trans_no']} AND debtor_trans_type = {$row['type']}";
279                 db_query($sql, "Could not delete debtor trans details");
280                 $sql = "DELETE FROM ".TB_PREF."debtor_trans WHERE trans_no = {$row['trans_no']} AND type = {$row['type']}";
281                 db_query($sql, "Could not delete debtor trans");
282                 delete_attachments_and_comments($row['type'], $row['trans_no']);
283         }
284         $sql = "SELECT trans_no, type FROM ".TB_PREF."supp_trans WHERE tran_date <= '$to' AND 
285                 ABS(ov_amount + ov_gst + ov_discount) = alloc";
286         $result = db_query($sql, "Could not retrieve supp trans");
287         while ($row = db_fetch($result))
288         {
289                 $sql = "DELETE FROM ".TB_PREF."supp_allocations WHERE trans_no_from = {$row['trans_no']} AND trans_type_from = {$row['type']}";
290                 db_query($sql, "Could not delete supp allocations");
291                 $sql = "DELETE FROM ".TB_PREF."supp_invoice_items WHERE supp_trans_no = {$row['trans_no']} AND supp_trans_type = {$row['type']}";
292                 db_query($sql, "Could not delete supp invoice items");
293                 $sql = "DELETE FROM ".TB_PREF."supp_trans WHERE trans_no = {$row['trans_no']} AND type = {$row['type']}";
294                 db_query($sql, "Could not delete supp trans");
295                 delete_attachments_and_comments($row['type'], $row['trans_no']);
296         }
297         $sql = "SELECT id FROM ".TB_PREF."workorders WHERE released_date <= '$to' AND closed=1";
298         $result = db_query($sql, "Could not retrieve supp trans");
299         while ($row = db_fetch($result))
300         {
301                 $sql = "SELECT issue_no FROM ".TB_PREF."wo_issues WHERE workorder_id = {$row['id']}"; 
302                 $res = db_query($sql, "Could not retrieve wo issues");
303                 while ($row2 = db_fetch_row($res))
304                 {
305                         $sql = "DELETE FROM ".TB_PREF."wo_issue_items WHERE issue_id = {$row2[0]}";
306                         db_query($sql, "Could not delete wo issue items");
307                 }       
308                 delete_attachments_and_comments(ST_MANUISSUE, $row['id']);
309                 $sql = "DELETE FROM ".TB_PREF."wo_issues WHERE workorder_id = {$row['id']}";
310                 db_query($sql, "Could not delete wo issues");
311                 $sql = "DELETE FROM ".TB_PREF."wo_manufacture WHERE workorder_id = {$row['id']}";
312                 db_query($sql, "Could not delete wo manufacture");
313                 $sql = "DELETE FROM ".TB_PREF."wo_requirements WHERE workorder_id = {$row['id']}";
314                 db_query($sql, "Could not delete wo requirements");
315                 $sql = "DELETE FROM ".TB_PREF."workorders WHERE id = {$row['id']}";
316                 db_query($sql, "Could not delete workorders");
317                 delete_attachments_and_comments(ST_WORKORDER, $row['id']);
318         }
319         $sql = "SELECT loc_code, stock_id, SUM(qty) AS qty, SUM(qty*standard_cost) AS std_cost FROM ".TB_PREF."stock_moves WHERE tran_date <= '$to' GROUP by 
320                 loc_code, stock_id";
321         $result = db_query($sql, "Could not retrieve supp trans");
322         while ($row = db_fetch($result))
323         {
324                 $sql = "DELETE FROM ".TB_PREF."stock_moves WHERE tran_date <= '$to' AND loc_code = '{$row['loc_code']}' AND stock_id = '{$row['stock_id']}'";
325                 db_query($sql, "Could not delete stock moves");
326                 $qty = $row['qty'];
327                 $std_cost = ($qty == 0 ? 0 : round2($row['std_cost'] / $qty, user_price_dec()));
328                 $sql = "INSERT INTO ".TB_PREF."stock_moves (stock_id, loc_code, tran_date, reference, qty, standard_cost) VALUES
329                         ('{$row['stock_id']}', '{$row['loc_code']}', '$to', '$ref', $qty, $std_cost)";   
330                 db_query($sql, "Could not insert stock move");
331         }               
332         $sql = "DELETE FROM ".TB_PREF."voided WHERE date_ <= '$to'";
333         db_query($sql, "Could not delete voided items");
334         $sql = "DELETE FROM ".TB_PREF."trans_tax_details WHERE tran_date <= '$to'";
335         db_query($sql, "Could not delete trans tax details");
336         $sql = "DELETE FROM ".TB_PREF."exchange_rates WHERE date_ <= '$to'";
337         db_query($sql, "Could not delete exchange rates");
338         $sql = "DELETE FROM ".TB_PREF."budget_trans WHERE tran_date <= '$to'";
339         db_query($sql, "Could not delete exchange rates");
340         $sql = "SELECT account, SUM(amount) AS amount, person_type_id, person_id FROM "
341                 .TB_PREF."gl_trans WHERE tran_date <= '$to' GROUP by account, person_type_id, person_id";
342         $result = db_query($sql, "Could not retrieve gl trans");
343         $trans_no = get_next_trans_no(ST_JOURNAL);
344
345         $last_account='';
346         $new = false;
347         while ($row = db_fetch($result))
348         {
349                 if ($last_account != $row['account']) // deletes all subledgers postings, so do it once for account
350                 {
351                         $sql = "DELETE FROM ".TB_PREF."gl_trans WHERE tran_date <= '$to' AND account = '{$row['account']}'";
352                         db_query($sql, "Could not delete gl trans");
353                         $last_account = $row['account'];
354                 }
355                 if (is_account_balancesheet($row['account']) && $row['amount'])
356                 {
357                         $sql = "INSERT INTO ".TB_PREF."gl_trans (type, type_no, tran_date, account, memo_, amount, person_type_id, person_id) VALUES
358                                 (".ST_JOURNAL.", $trans_no, '$to', '{$row['account']}', '$ref', {$row['amount']}, "
359                                 .db_escape($row['person_type_id'], true).", ".db_escape($row['person_id'], true).")";
360                         db_query($sql, "Could not insert gl trans");
361                         $new = true;
362                 }
363         }
364         if ($new)
365         {
366                 global $Refs;
367                 $trans_type = ST_JOURNAL;
368                 $reference = $Refs->get_next($trans_type);
369                 $Refs->save($trans_type, $trans_no, $reference);
370                 $date_ = sql2date($to);
371
372                 add_audit_trail($trans_type, $trans_no, $date_);
373         }
374         $sql = "SELECT bank_act, SUM(amount) AS amount FROM ".TB_PREF."bank_trans WHERE trans_date <= '$to' GROUP BY bank_act";
375         $result = db_query($sql, "Could not retrieve bank trans");
376         while ($row = db_fetch($result))
377         {
378                 $sql = "DELETE FROM ".TB_PREF."bank_trans WHERE trans_date <= '$to' AND bank_act = '{$row['bank_act']}'";
379                 db_query($sql, "Could not delete bank trans");
380                 $sql = "INSERT INTO ".TB_PREF."bank_trans (type, trans_no, trans_date, bank_act, ref, amount) VALUES
381                         (0, 0, '$to', '{$row['bank_act']}', '$ref', {$row['amount']})";
382                 db_query($sql, "Could not insert bank trans");
383         }       
384         
385         $sql = "DELETE FROM ".TB_PREF."audit_trail WHERE gl_date <= '$to'";
386         db_query($sql, "Could not delete audit trail");
387         
388         $sql = "SELECT type, id FROM ".TB_PREF."comments WHERE type != ".ST_SALESQUOTE." AND type != ".ST_SALESORDER." AND type != ".ST_PURCHORDER;
389         $result = db_query($sql, "Could not retrieve comments");
390         while ($row = db_fetch($result))
391         {
392                 $sql = "SELECT count(*) FROM ".TB_PREF."gl_trans WHERE type = {$row['type']} AND type_no = {$row['id']}";
393                 $res = db_query($sql, "Could not retrieve gl_trans");
394                 $row2 = db_fetch_row($res);
395                 if ($row2[0] == 0) // if no link, then delete comments
396                 {
397                         $sql = "DELETE FROM ".TB_PREF."comments WHERE type = {$row['type']} AND id = {$row['id']}";
398                         db_query($sql, "Could not delete comments");
399                 }
400         }       
401         $sql = "SELECT type, id FROM ".TB_PREF."refs WHERE type != ".ST_SALESQUOTE." AND type != ".ST_SALESORDER." AND type != ".ST_PURCHORDER;
402         $result = db_query($sql, "Could not retrieve refs");
403         while ($row = db_fetch($result))
404         {
405                 $sql = "SELECT count(*) FROM ".TB_PREF."gl_trans WHERE type = {$row['type']} AND type_no = {$row['id']}";
406                 $res = db_query($sql, "Could not retrieve gl_trans");
407                 $row2 = db_fetch_row($res);
408                 if ($row2[0] == 0) // if no link, then delete refs
409                 {
410                         $sql = "DELETE FROM ".TB_PREF."refs WHERE type = {$row['type']} AND id = {$row['id']}";
411                         db_query($sql, "Could not delete refs");
412                 }
413         }       
414                 
415         delete_fiscalyear($selected_id);
416         commit_transaction();   
417 }
418
419
420 ?>