2 // +----------------------------------------------------------------------+
3 // | Anuko Time Tracker
4 // +----------------------------------------------------------------------+
5 // | Copyright (c) Anuko International Ltd. (https://www.anuko.com)
6 // +----------------------------------------------------------------------+
7 // | LIBERAL FREEWARE LICENSE: This source code document may be used
8 // | by anyone for any purpose, and freely redistributed alone or in
9 // | combination with other software, provided that the license is obeyed.
11 // | There are only two ways to violate the license:
13 // | 1. To redistribute this code in source form, with the copyright
14 // | notice or license removed or altered. (Distributing in compiled
15 // | forms without embedded copyright notices is permitted).
17 // | 2. To redistribute modified versions of this code in *any* form
18 // | that bears insufficient indications that the modifications are
19 // | not the work of the original author(s).
21 // | This license applies to this document only, not any other software
22 // | that it may be combined with.
24 // +----------------------------------------------------------------------+
26 // | https://www.anuko.com/time_tracker/credits.htm
27 // +----------------------------------------------------------------------+
29 import('ttClientHelper');
30 import('DateAndTime');
32 // Class ttInvoiceHelper is used for help with invoices.
33 class ttInvoiceHelper {
35 // getInvoice - obtains invoice data from the database.
36 static function getInvoice($invoice_id) {
38 $mdb2 = getConnection();
40 $group_id = $user->getGroup();
41 $org_id = $user->org_id;
43 if ($user->isClient()) $client_part = "and client_id = $user->client_id";
45 $sql = "select * from tt_invoices".
46 " where id = $invoice_id and group_id = $group_id and org_id = $org_id $client_part and status = 1";
47 $res = $mdb2->query($sql);
48 if (!is_a($res, 'PEAR_Error')) {
49 if ($val = $res->fetchRow())
55 // The getInvoiceByName looks up an invoice by name.
56 static function getInvoiceByName($invoice_name) {
58 $mdb2 = getConnection();
60 $group_id = $user->getGroup();
61 $org_id = $user->org_id;
63 $sql = "select id from tt_invoices where group_id = $group_id and org_id = $org_id".
64 " and name = ".$mdb2->quote($invoice_name)." and status = 1";
65 $res = $mdb2->query($sql);
66 if (!is_a($res, 'PEAR_Error')) {
67 $val = $res->fetchRow();
75 // The isPaid determines if an invoice is paid by looking at the paid status of its items.
76 // If any non-paid item is found, the entire invoice is considered not paid.
77 // Therefore, the paid status of the invoice is a calculated value.
78 // This is because we maintain the paid status on individual item level.
79 static function isPaid($invoice_id) {
81 $mdb2 = getConnection();
83 $group_id = $user->getGroup();
84 $org_id = $user->org_id;
86 $sql = "select count(*) as count from tt_log".
87 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id and status = 1 and paid < 1";
88 $res = $mdb2->query($sql);
89 if (!is_a($res, 'PEAR_Error')) {
90 $val = $res->fetchRow();
91 if ($val['count'] > 0)
92 return false; // A non-paid time item exists.
94 $sql = "select count(*) as count from tt_expense_items".
95 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id and status = 1 and paid < 1";
96 $res = $mdb2->query($sql);
97 if (!is_a($res, 'PEAR_Error')) {
98 $val = $res->fetchRow();
99 if ($val['count'] > 0)
100 return false; // A non-paid expense item exists.
102 return true; // All time and expense items in invoice are paid.
107 // markPaid marks invoice items as paid.
108 static function markPaid($invoice_id, $mark_paid = true) {
110 $mdb2 = getConnection();
112 $group_id = $user->getGroup();
113 $org_id = $user->org_id;
115 $paid_status = $mark_paid ? 1 : 0;
116 $sql = "update tt_log set paid = $paid_status".
117 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id and status = 1";
118 $affected = $mdb2->exec($sql);
119 if (is_a($affected, 'PEAR_Error')) return false;
121 $sql = "update tt_expense_items set paid = $paid_status".
122 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id and status = 1";
123 $affected = $mdb2->exec($sql);
124 if (is_a($affected, 'PEAR_Error')) return false;
129 // The getInvoiceItems retrieves tt_log items associated with the invoice.
130 static function getInvoiceItems($invoice_id) {
132 $mdb2 = getConnection();
134 $group_id = $user->getGroup();
135 $org_id = $user->org_id;
137 // At this time only detailed invoice is supported.
138 // It is anticipated to support "totals only" option later on.
140 // Our query is different depending on tracking mode.
141 if (MODE_TIME == $user->getTrackingMode()) {
142 // In "time only" tracking mode there is a single user rate.
143 $sql = "select l.date as date, 1 as type, u.name as user_name, p.name as project_name,".
144 " t.name as task_name, l.comment as note, time_format(l.duration, '%k:%i') as duration,".
145 " cast(l.billable * u.rate * time_to_sec(l.duration)/3600 as decimal(10, 2)) as cost,".
146 " l.paid as paid from tt_log l".
147 " inner join tt_users u on (l.user_id = u.id)".
148 " left join tt_projects p on (p.id = l.project_id)".
149 " left join tt_tasks t on (t.id = l.task_id)".
150 " where l.status = 1 and l.billable = 1 and l.invoice_id = $invoice_id".
151 " and l.group_id = $group_id and l.org_id = $org_id order by l.date, u.name";
153 $sql = "select l.date as date, 1 as type, u.name as user_name, p.name as project_name,".
154 " t.name as task_name, l.comment as note, time_format(l.duration, '%k:%i') as duration,".
155 " cast(l.billable * coalesce(upb.rate, 0) * time_to_sec(l.duration)/3600 as decimal(10, 2)) as cost,".
156 " l.paid as paid from tt_log l".
157 " inner join tt_users u on (l.user_id = u.id)".
158 " left join tt_projects p on (p.id = l.project_id)".
159 " left join tt_tasks t on (t.id = l.task_id)".
160 " left join tt_user_project_binds upb on (upb.user_id = l.user_id and upb.project_id = l.project_id)".
161 " where l.status = 1 and l.billable = 1 and l.invoice_id = $invoice_id".
162 " and l.group_id = $group_id and l.org_id = $org_id order by l.date, u.name";
165 // If we have expenses, we need to do a union with a separate query for expense items from tt_expense_items table.
166 if ($user->isPluginEnabled('ex')) {
167 $sql_for_expense_items = "select ei.date as date, 2 as type, u.name as user_name, p.name as project_name,".
168 " null as task_name, ei.name as note,".
169 " null as duration, ei.cost as cost,".
170 " ei.paid as paid from tt_expense_items ei".
171 " inner join tt_users u on (ei.user_id = u.id)".
172 " left join tt_projects p on (p.id = ei.project_id)".
173 " where ei.invoice_id = $invoice_id and ei.group_id = $group_id and ei.org_id = $org_id and ei.status = 1";
175 // Construct a union.
176 $sql = "($sql) union all ($sql_for_expense_items)";
178 $sort_part = " order by date, user_name, type";
182 $res = $mdb2->query($sql);
183 if (!is_a($res, 'PEAR_Error')) {
184 $dt = new DateAndTime(DB_DATEFORMAT);
185 while ($val = $res->fetchRow()) {
186 $dt->parseVal($val['date']);
187 $val['date'] = $dt->toString($user->getDateFormat());
194 // delete - deletes the invoice data from the database.
195 static function delete($invoice_id, $delete_invoice_items) {
197 $mdb2 = getConnection();
199 $group_id = $user->getGroup();
200 $org_id = $user->org_id;
202 // Handle custom field log records.
203 if ($delete_invoice_items) {
204 $sql = "update tt_custom_field_log set status = null".
206 " (select id from tt_log where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id and status = 1)";
207 $affected = $mdb2->exec($sql);
208 if (is_a($affected, 'PEAR_Error')) return false;
211 // Handle time records.
212 if ($delete_invoice_items) {
213 $sql = "update tt_log set status = null".
214 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id";
216 $sql = "update tt_log set invoice_id = null".
217 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id";
219 $affected = $mdb2->exec($sql);
220 if (is_a($affected, 'PEAR_Error')) return false;
222 // Handle expense items.
223 if ($delete_invoice_items) {
224 $sql = "update tt_expense_items set status = null".
225 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id";
227 $sql = "update tt_expense_items set invoice_id = null".
228 " where invoice_id = $invoice_id and group_id = $group_id and org_id = $org_id";
230 $affected = $mdb2->exec($sql);
231 if (is_a($affected, 'PEAR_Error')) return false;
233 $sql = "update tt_invoices set status = null".
234 " where id = $invoice_id and group_id = $group_id and org_id = $org_id";
235 $affected = $mdb2->exec($sql);
236 return (!is_a($affected, 'PEAR_Error'));
239 // The invoiceableItemsExist determines whether invoiceable records exist in the specified period.
240 static function invoiceableItemsExist($fields) {
242 $mdb2 = getConnection();
244 $group_id = $user->getGroup();
245 $org_id = $user->org_id;
247 $client_id = (int) $fields['client_id'];
249 $start_date = new DateAndTime($user->date_format, $fields['start_date']);
250 $start = $start_date->toString(DB_DATEFORMAT);
252 $end_date = new DateAndTime($user->date_format, $fields['end_date']);
253 $end = $end_date->toString(DB_DATEFORMAT);
255 if (isset($fields['project_id'])) $project_id = (int) $fields['project_id'];
257 // Our query is different depending on tracking mode.
258 if (MODE_TIME == $user->getTrackingMode()) {
259 // In "time only" tracking mode there is a single user rate.
260 $sql = "select count(*) as num from tt_log l, tt_users u".
261 " where l.status = 1 and l.client_id = $client_id and l.invoice_id is null".
262 " and l.date >= ".$mdb2->quote($start)." and l.date <= ".$mdb2->quote($end).
263 " and l.user_id = u.id and l.group_id = $group_id and l.org_id = $org_id".
264 " and l.billable = 1"; // l.billable * u.rate * time_to_sec(l.duration)/3600 > 0 // See explanation below.
266 // sql part for project id.
267 if ($project_id) $project_part = " and l.project_id = $project_id";
269 // When we have projects, rates are defined for each project in tt_user_project_binds table.
270 $sql = "select count(*) as num from tt_log l, tt_user_project_binds upb".
271 " where l.status = 1 and l.client_id = $client_id $project_part and l.invoice_id is null".
272 " and l.date >= ".$mdb2->quote($start)." and l.date <= ".$mdb2->quote($end).
273 " and l.group_id = $group_id and l.org_id = $org_id".
274 " and upb.user_id = l.user_id and upb.project_id = l.project_id".
275 " and l.billable = 1"; // l.billable * upb.rate * time_to_sec(l.duration)/3600 > 0
276 // Users with a lot of clients and projects (Jaro) may forget to set user rates properly.
277 // Specifically, user rate may be set to 0 on a project, by mistake. This leads to error.no_invoiceable_items
278 // and increased support cost. Commenting out allows us to include 0 cost items in invoices so that
279 // the problem becomes obvious.
281 // TODO: If the above turns out useful, rework the query to simplify it by removing left join.
283 $res = $mdb2->query($sql);
284 if (!is_a($res, 'PEAR_Error')) {
285 $val = $res->fetchRow();
291 if ($user->isPluginEnabled('ex')) {
292 // sql part for project id.
293 if ($project_id) $project_part = " and ei.project_id = $project_id";
295 $sql = "select count(*) as num from tt_expense_items ei".
296 " where ei.client_id = $client_id $project_part and ei.invoice_id is null".
297 " and ei.date >= ".$mdb2->quote($start)." and ei.date <= ".$mdb2->quote($end).
298 " and ei.group_id = $group_id and ei.org_id = $org_id".
299 " and ei.cost <> 0 and ei.status = 1";
300 $res = $mdb2->query($sql);
301 if (!is_a($res, 'PEAR_Error')) {
302 $val = $res->fetchRow();
312 // createInvoice - marks items for invoice as belonging to it (with its reference number).
313 static function createInvoice($fields) {
315 $mdb2 = getConnection();
317 $group_id = $user->getGroup();
318 $org_id = $user->org_id;
320 $name = $fields['name'];
321 if (!$name) return false;
323 $client_id = (int) $fields['client_id'];
325 $invoice_date = new DateAndTime($user->date_format, $fields['date']);
326 $date = $invoice_date->toString(DB_DATEFORMAT);
328 $start_date = new DateAndTime($user->date_format, $fields['start_date']);
329 $start = $start_date->toString(DB_DATEFORMAT);
331 $end_date = new DateAndTime($user->date_format, $fields['end_date']);
332 $end = $end_date->toString(DB_DATEFORMAT);
334 if (isset($fields['project_id'])) $project_id = (int) $fields['project_id'];
336 // Create a new invoice record.
337 $sql = "insert into tt_invoices (group_id, org_id, name, date, client_id)".
338 " values($group_id, $org_id, ".$mdb2->quote($name).", ".$mdb2->quote($date).", $client_id)";
339 $affected = $mdb2->exec($sql);
340 if (is_a($affected, 'PEAR_Error')) return false;
342 // Mark associated invoice items with invoice id.
343 $last_id = $mdb2->lastInsertID('tt_invoices', 'id');
345 // Our update sql is different depending on tracking mode.
346 if (MODE_TIME == $user->getTrackingMode()) {
347 // In "time only" tracking mode there is a single user rate.
348 $sql = "update tt_log l".
349 " left join tt_users u on (u.id = l.user_id)".
350 " set l.invoice_id = $last_id".
351 " where l.status = 1 and l.client_id = $client_id and l.invoice_id is null".
352 " and l.group_id = $group_id and l.org_id = $org_id".
353 " and l.date >= ".$mdb2->quote($start)." and l.date <= ".$mdb2->quote($end).
354 " and l.duration > 0 and l.billable = 1"; // l.billable * u.rate * time_to_sec(l.duration)/3600 > 0"; // See explanation below.
356 // sql part for project id.
357 if ($project_id) $project_part = " and l.project_id = $project_id";
359 // When we have projects, rates are defined for each project in tt_user_project_binds.
360 $sql = "update tt_log l".
361 " left join tt_user_project_binds upb on (upb.user_id = l.user_id and upb.project_id = l.project_id)".
362 " set l.invoice_id = $last_id".
363 " where l.status = 1 and l.client_id = $client_id $project_part and l.invoice_id is null".
364 " and l.group_id = $group_id and l.org_id = $org_id".
365 " and l.date >= ".$mdb2->quote($start)." and l.date <= ".$mdb2->quote($end).
366 " and l.duration > 0 and l.billable = 1"; // l.billable * upb.rate * time_to_sec(l.duration)/3600 > 0";
367 // Users with a lot of clients and projects (Jaro) may forget to set user rates properly.
368 // Specifically, user rate may be set to 0 on a project, by mistake. This leads to error.no_invoiceable_items
369 // and increased support cost. Commenting out allows us to include 0 cost items in invoices so that
370 // the problem becomes obvious.
372 // TODO: If the above turns out useful, rework the query to simplify it by removing left join.
374 $affected = $mdb2->exec($sql);
375 if (is_a($affected, 'PEAR_Error'))
378 // sql part for project id.
379 if ($project_id) $project_part = " and project_id = $project_id";
381 $sql = "update tt_expense_items set invoice_id = $last_id".
382 " where client_id = $client_id $project_part and invoice_id is null".
383 " and group_id = $group_id and org_id = $org_id".
384 " and date >= ".$mdb2->quote($start)." and date <= ".$mdb2->quote($end)." and cost <> 0 and status = 1";
385 $affected = $mdb2->exec($sql);
386 return (!is_a($affected, 'PEAR_Error'));
389 // prepareInvoiceBody - prepares an email body for invoice.
390 static function prepareInvoiceBody($invoice_id, $comment)
395 $currency = $user->getCurrency();
396 $decimalMark = $user->getDecimalMark();
398 $invoice = ttInvoiceHelper::getInvoice($invoice_id);
399 $client = ttClientHelper::getClient($invoice['client_id'], true);
400 $invoice_items = ttInvoiceHelper::getInvoiceItems($invoice_id);
402 $tax_percent = $client['tax'];
406 foreach($invoice_items as $item)
407 $subtotal += $item['cost'];
409 $tax_expenses = $user->isPluginEnabled('et');
410 foreach($invoice_items as $item) {
411 if ($item['type'] == 2 && !$tax_expenses)
413 $tax += round($item['cost'] * $tax_percent / 100, 2);
416 $total = $subtotal + $tax;
418 $subtotal = htmlspecialchars($currency).' '.str_replace('.', $decimalMark, sprintf('%8.2f', round($subtotal, 2)));
419 if ($tax) $tax = htmlspecialchars($currency).' '.str_replace('.', $decimalMark, sprintf('%8.2f', round($tax, 2)));
420 $total = htmlspecialchars($currency).' '.str_replace('.', $decimalMark, sprintf('%8.2f', round($total, 2)));
422 if ('.' != $decimalMark) {
423 foreach ($invoice_items as &$item) {
424 $item['cost'] = str_replace('.', $decimalMark, $item['cost']);
426 unset($item); // Unset the reference. If we don't, the foreach loop below modifies the array while printing.
427 // See http://stackoverflow.com/questions/8220399/php-foreach-pass-by-reference-last-element-duplicating-bug
430 // Define some styles to use in email.
431 $style_title = 'text-align: center; font-size: 15pt; font-family: Arial, Helvetica, sans-serif;';
432 $style_tableHeader = 'font-weight: bold; background-color: #a6ccf7; text-align: left;';
433 $style_tableHeaderCentered = 'font-weight: bold; background-color: #a6ccf7; text-align: center;';
435 // Determine tracking mode once for multiple reuse below.
436 $trackingMode = $user->getTrackingMode();
438 // Start creating email body.
440 $body .= '<head><meta http-equiv="content-type" content="text/html; charset='.CHARSET.'"></head>';
444 $body .= '<p style="'.$style_title.'">'.$i18n->get('title.invoice').' '.htmlspecialchars($invoice['name']).'</p>';
447 if($comment) $body .= '<p>'.htmlspecialchars($comment).'</p>';
449 // Output invoice info.
451 $body .= '<tr><td><b>'.$i18n->get('label.date').':</b> '.$invoice['date'].'</td></tr>';
452 $body .= '<tr><td><b>'.$i18n->get('label.client').':</b> '.htmlspecialchars($client['name']).'</td></tr>';
453 $body .= '<tr><td><b>'.$i18n->get('label.client_address').':</b> '.htmlspecialchars($client['address']).'</td></tr>';
458 // Output invoice items.
459 $body .= '<table border="0" cellpadding="4" cellspacing="0" width="100%">';
461 $body .= '<td style="'.$style_tableHeader.'">'.$i18n->get('label.date').'</td>';
462 $body .= '<td style="'.$style_tableHeader.'">'.$i18n->get('form.invoice.person').'</td>';
463 if (MODE_PROJECTS == $trackingMode || MODE_PROJECTS_AND_TASKS == $trackingMode)
464 $body .= '<td style="'.$style_tableHeader.'">'.$i18n->get('label.project').'</td>';
465 if (MODE_PROJECTS_AND_TASKS == $trackingMode)
466 $body .= '<td style="'.$style_tableHeader.'">'.$i18n->get('label.task').'</td>';
467 $body .= '<td style="'.$style_tableHeader.'">'.$i18n->get('label.note').'</td>';
468 $body .= '<td style="'.$style_tableHeaderCentered.'" width="5%">'.$i18n->get('label.duration').'</td>';
469 $body .= '<td style="'.$style_tableHeaderCentered.'" width="5%">'.$i18n->get('label.cost').'</td>';
471 foreach ($invoice_items as $item) {
473 $body .= '<td>'.$item['date'].'</td>';
474 $body .= '<td>'.htmlspecialchars($item['user_name']).'</td>';
475 if (MODE_PROJECTS == $trackingMode || MODE_PROJECTS_AND_TASKS == $trackingMode)
476 $body .= '<td>'.htmlspecialchars($item['project_name']).'</td>';
477 if (MODE_PROJECTS_AND_TASKS == $trackingMode)
478 $body .= '<td>'.htmlspecialchars($item['task_name']).'</td>';
479 $body .= '<td>'.htmlspecialchars($item['note']).'</td>';
480 $body .= '<td align="right">'.$item['duration'].'</td>';
481 $body .= '<td align="right">'.$item['cost'].'</td>';
486 if (MODE_PROJECTS == $trackingMode)
488 elseif (MODE_PROJECTS_AND_TASKS == $trackingMode)
490 $body .= '<tr><td> </td></tr>';
492 $body .= '<tr><td colspan="'.$colspan.'" align="right"><b>'.$i18n->get('label.subtotal').':</b></td><td nowrap align="right">'.$subtotal.'</td></tr>';
493 $body .= '<tr><td colspan="'.$colspan.'" align="right"><b>'.$i18n->get('label.tax').':</b></td><td nowrap align="right">'.$tax.'</td></tr>';
495 $body .= '<tr><td colspan="'.$colspan.'" align="right"><b>'.$i18n->get('label.total').':</b></td><td nowrap align="right">'.$total.'</td></tr>';
499 if (!defined('REPORT_FOOTER') || !(REPORT_FOOTER == false))
500 $body .= '<p style="text-align: center;">'.$i18n->get('form.mail.footer').'</p>';
502 // Finish creating email body.
503 $body .= '</body></html>';