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 import('ttTimeHelper');
34 require_once(dirname(__FILE__).'/../../plugins/CustomFields.class.php');
36 // Definitions of types for timesheet dropdown.
37 define('TIMESHEET_ALL', 0); // Include all records.
38 define('TIMESHEET_NOT_ASSIGNED', 1); // Include records not assigned to timesheets.
39 define('TIMESHEET_ASSIGNED', 2); // Include records assigned to timesheets.
40 define('TIMESHEET_PENDING', 3); // Include records in submitted timesheets that are pending manager approval.
41 define('TIMESHEET_APPROVED', 4); // Include records in approved timesheets.
42 define('TIMESHEET_NOT_APPROVED', 5); // Include records in disapproved timesheets.
44 // Class ttReportHelper is used for help with reports.
45 class ttReportHelper {
47 // getWhere prepares a WHERE clause for a report query.
48 static function getWhere($options) {
51 $group_id = $user->getGroup();
52 $org_id = $user->org_id;
54 // A shortcut for timesheets.
55 if ($options['timesheet_id']) {
56 $where = " where l.timesheet_id = ".$options['timesheet_id']." and l.group_id = $group_id and l.org_id = $org_id";
60 // Prepare dropdown parts.
62 if ($options['client_id'])
63 $dropdown_parts .= ' and l.client_id = '.$options['client_id'];
64 elseif ($user->isClient() && $user->client_id)
65 $dropdown_parts .= ' and l.client_id = '.$user->client_id;
66 if ($options['cf_1_option_id']) $dropdown_parts .= ' and l.id in(select log_id from tt_custom_field_log where status = 1 and option_id = '.$options['cf_1_option_id'].')';
67 if ($options['project_id']) $dropdown_parts .= ' and l.project_id = '.$options['project_id'];
68 if ($options['task_id']) $dropdown_parts .= ' and l.task_id = '.$options['task_id'];
69 if ($options['billable']=='1') $dropdown_parts .= ' and l.billable = 1';
70 if ($options['billable']=='2') $dropdown_parts .= ' and l.billable = 0';
71 if ($options['invoice']=='1') $dropdown_parts .= ' and l.invoice_id is not null';
72 if ($options['invoice']=='2') $dropdown_parts .= ' and l.invoice_id is null';
73 if ($options['timesheet']==TIMESHEET_NOT_ASSIGNED) $dropdown_parts .= ' and l.timesheet_id is null';
74 if ($options['timesheet']==TIMESHEET_ASSIGNED) $dropdown_parts .= ' and l.timesheet_id is not null';
75 if ($options['approved']=='1') $dropdown_parts .= ' and l.approved = 1';
76 if ($options['approved']=='2') $dropdown_parts .= ' and l.approved = 0';
77 if ($options['paid_status']=='1') $dropdown_parts .= ' and l.paid = 1';
78 if ($options['paid_status']=='2') $dropdown_parts .= ' and l.paid = 0';
80 // Prepare sql query part for user list.
81 $userlist = $options['users'] ? $options['users'] : '-1';
82 if ($user->can('view_reports') || $user->can('view_all_reports') || $user->isClient())
83 $user_list_part = " and l.user_id in ($userlist)";
85 $user_list_part = " and l.user_id = ".$user->getUser();
86 $user_list_part .= " and l.group_id = $group_id and l.org_id = $org_id";
88 // Prepare sql query part for where.
89 $dateFormat = $user->getDateFormat();
90 if ($options['period'])
91 $period = new Period($options['period'], new DateAndTime($dateFormat));
93 $period = new Period();
95 new DateAndTime($dateFormat, $options['period_start']),
96 new DateAndTime($dateFormat, $options['period_end']));
98 $where = " where l.status = 1 and l.date >= '".$period->getStartDate(DB_DATEFORMAT)."' and l.date <= '".$period->getEndDate(DB_DATEFORMAT)."'".
99 " $user_list_part $dropdown_parts";
103 // getExpenseWhere prepares WHERE clause for expenses query in a report.
104 static function getExpenseWhere($options) {
107 $group_id = $user->getGroup();
108 $org_id = $user->org_id;
110 // Prepare dropdown parts.
111 $dropdown_parts = '';
112 if ($options['client_id'])
113 $dropdown_parts .= ' and ei.client_id = '.$options['client_id'];
114 elseif ($user->isClient() && $user->client_id)
115 $dropdown_parts .= ' and ei.client_id = '.$user->client_id;
116 if ($options['project_id']) $dropdown_parts .= ' and ei.project_id = '.$options['project_id'];
117 if ($options['invoice']=='1') $dropdown_parts .= ' and ei.invoice_id is not null';
118 if ($options['invoice']=='2') $dropdown_parts .= ' and ei.invoice_id is null';
119 if (isset($options['timesheet']) && ($options['timesheet']!=TIMESHEET_ALL && $options['timesheet']!=TIMESHEET_NOT_ASSIGNED)) {
120 $dropdown_parts .= ' and 0 = 1'; // Expense items do not have a timesheet_id.
122 if ($options['approved']=='1') $dropdown_parts .= ' and ei.approved = 1';
123 if ($options['approved']=='2') $dropdown_parts .= ' and ei.approved = 0';
124 if ($options['paid_status']=='1') $dropdown_parts .= ' and ei.paid = 1';
125 if ($options['paid_status']=='2') $dropdown_parts .= ' and ei.paid = 0';
127 // Prepare sql query part for user list.
128 $userlist = $options['users'] ? $options['users'] : '-1';
129 if ($user->can('view_reports') || $user->can('view_all_reports') || $user->isClient())
130 $user_list_part = " and ei.user_id in ($userlist)";
132 $user_list_part = " and ei.user_id = ".$user->getUser();
133 $user_list_part .= " and ei.group_id = $group_id and ei.org_id = $org_id";
135 // Prepare sql query part for where.
136 $dateFormat = $user->getDateFormat();
137 if ($options['period'])
138 $period = new Period($options['period'], new DateAndTime($dateFormat));
140 $period = new Period();
142 new DateAndTime($dateFormat, $options['period_start']),
143 new DateAndTime($dateFormat, $options['period_end']));
145 $where = " where ei.status = 1 and ei.date >= '".$period->getStartDate(DB_DATEFORMAT)."' and ei.date <= '".$period->getEndDate(DB_DATEFORMAT)."'".
146 " $user_list_part $dropdown_parts";
150 // getItems retrieves all items associated with a report.
151 // It combines tt_log and tt_expense_items in one array for presentation in one table using mysql union all.
152 // Expense items use the "note" field for item name.
153 static function getItems($options) {
155 $mdb2 = getConnection();
157 $group_id = $user->getGroup();
158 $org_id = $user->org_id;
160 // Determine these once as they are used in multiple places in this function.
161 $canViewReports = $user->can('view_reports') || $user->can('view_all_reports');
162 $isClient = $user->isClient();
164 $grouping = ttReportHelper::grouping($options);
166 $grouping_by_date = ttReportHelper::groupingBy('date', $options);
167 $grouping_by_client = ttReportHelper::groupingBy('client', $options);
168 $grouping_by_project = ttReportHelper::groupingBy('project', $options);
169 $grouping_by_task = ttReportHelper::groupingBy('task', $options);
170 $grouping_by_user = ttReportHelper::groupingBy('user', $options);
171 $grouping_by_cf_1 = ttReportHelper::groupingBy('cf_1', $options);
173 $convertTo12Hour = ('%I:%M %p' == $user->getTimeFormat()) && ($options['show_start'] || $options['show_end']);
174 $trackingMode = $user->getTrackingMode();
175 $decimalMark = $user->getDecimalMark();
177 // Prepare a query for time items in tt_log table.
178 $fields = array(); // An array of fields for database query.
179 array_push($fields, 'l.id');
180 array_push($fields, 'l.user_id');
181 array_push($fields, '1 as type'); // Type 1 is for tt_log entries.
182 array_push($fields, 'l.date');
183 if($canViewReports || $isClient)
184 array_push($fields, 'u.name as user');
185 // Add client name if it is selected.
186 if ($options['show_client'] || $grouping_by_client)
187 array_push($fields, 'c.name as client');
188 // Add project name if it is selected.
189 if ($options['show_project'] || $grouping_by_project)
190 array_push($fields, 'p.name as project');
191 // Add task name if it is selected.
192 if ($options['show_task'] || $grouping_by_task)
193 array_push($fields, 't.name as task');
195 $include_cf_1 = $options['show_custom_field_1'] || $grouping_by_cf_1;
197 $custom_fields = new CustomFields();
198 $cf_1_type = $custom_fields->fields[0]['type'];
199 if ($cf_1_type == CustomFields::TYPE_TEXT) {
200 array_push($fields, 'cfl.value as cf_1');
201 } elseif ($cf_1_type == CustomFields::TYPE_DROPDOWN) {
202 array_push($fields, 'cfo.value as cf_1');
206 if ($options['show_start']) {
207 array_push($fields, "l.start as unformatted_start");
208 array_push($fields, "TIME_FORMAT(l.start, '%k:%i') as start");
211 if ($options['show_end'])
212 array_push($fields, "TIME_FORMAT(sec_to_time(time_to_sec(l.start) + time_to_sec(l.duration)), '%k:%i') as finish");
214 if ($options['show_duration'])
215 array_push($fields, "TIME_FORMAT(l.duration, '%k:%i') as duration");
217 if ($options['show_work_units']) {
218 if ($user->getConfigOption('unit_totals_only'))
219 array_push($fields, "null as units");
221 $firstUnitThreshold = $user->getConfigInt('1st_unit_threshold', 0);
222 $minutesInUnit = $user->getConfigInt('minutes_in_unit', 15);
223 array_push($fields, "if(l.billable = 0 or time_to_sec(l.duration)/60 < $firstUnitThreshold, 0, ceil(time_to_sec(l.duration)/60/$minutesInUnit)) as units");
227 if ($options['show_note'])
228 array_push($fields, 'l.comment as note');
230 $includeCost = $options['show_cost'];
232 if (MODE_TIME == $trackingMode)
233 array_push($fields, "cast(l.billable * coalesce(u.rate, 0) * time_to_sec(l.duration)/3600 as decimal(10,2)) as cost"); // Use default user rate.
235 array_push($fields, "cast(l.billable * coalesce(upb.rate, 0) * time_to_sec(l.duration)/3600 as decimal(10,2)) as cost"); // Use project rate for user.
236 array_push($fields, "null as expense");
239 if ($options['show_approved'])
240 array_push($fields, 'l.approved');
242 if ($canViewReports && $options['show_paid'])
243 array_push($fields, 'l.paid');
245 if ($canViewReports && $options['show_ip']) {
246 array_push($fields, 'l.created');
247 array_push($fields, 'l.created_ip');
248 array_push($fields, 'l.modified');
249 array_push($fields, 'l.modified_ip');
251 // Add invoice name if it is selected.
252 if (($canViewReports || $isClient) && $options['show_invoice'])
253 array_push($fields, 'i.name as invoice');
254 // Add timesheet name if it is selected.
255 if ($options['show_timesheet'])
256 array_push($fields, 'ts.name as timesheet_name');
258 if ($options['show_files'])
259 array_push($fields, 'if(Sub1.entity_id is null, 0, 1) as has_files');
261 // Prepare sql query part for left joins.
263 if ($options['show_client'] || $grouping_by_client)
264 $left_joins .= " left join tt_clients c on (c.id = l.client_id)";
265 if (($canViewReports || $isClient) && $options['show_invoice'])
266 $left_joins .= " left join tt_invoices i on (i.id = l.invoice_id and i.status = 1)";
267 if ($canViewReports || $isClient || $user->isPluginEnabled('ex'))
268 $left_joins .= " left join tt_users u on (u.id = l.user_id)";
269 if ($options['show_project'] || $grouping_by_project)
270 $left_joins .= " left join tt_projects p on (p.id = l.project_id)";
271 if ($options['show_task'] || $grouping_by_task)
272 $left_joins .= " left join tt_tasks t on (t.id = l.task_id)";
274 if ($cf_1_type == CustomFields::TYPE_TEXT)
275 $left_joins .= " left join tt_custom_field_log cfl on (l.id = cfl.log_id and cfl.status = 1)";
276 elseif ($cf_1_type == CustomFields::TYPE_DROPDOWN) {
277 $left_joins .= " left join tt_custom_field_log cfl on (l.id = cfl.log_id and cfl.status = 1)".
278 " left join tt_custom_field_options cfo on (cfl.option_id = cfo.id)";
281 if ($includeCost && MODE_TIME != $trackingMode)
282 $left_joins .= " left join tt_user_project_binds upb on (l.user_id = upb.user_id and l.project_id = upb.project_id)";
283 if ($options['show_files']) {
284 $left_joins .= " left join (select distinct entity_id from tt_files".
285 " where entity_type = 'time' and group_id = $group_id and org_id = $org_id and status = 1) Sub1".
286 " on (l.id = Sub1.entity_id)";
289 // Prepare sql query part for inner joins.
291 if ($user->isPluginEnabled('ts')) {
292 $timesheet_option = $options['timesheet'];
293 if ($timesheet_option == TIMESHEET_PENDING)
294 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.submit_status = 1 and ts.approve_status is null)";
295 else if ($timesheet_option == TIMESHEET_APPROVED)
296 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.approve_status = 1)";
297 else if ($timesheet_option == TIMESHEET_NOT_APPROVED)
298 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.approve_status = 0)";
299 else if ($options['show_timesheet'])
300 $inner_joins .= " left join tt_timesheets ts on (l.timesheet_id = ts.id)"; // Left join for timesheet nme.
303 $where = ttReportHelper::getWhere($options);
305 // Construct sql query for tt_log items.
306 $sql = "select ".join(', ', $fields)." from tt_log l $left_joins $inner_joins $where";
307 // If we don't have expense items (such as when the Expenses plugin is disabled), the above is all sql we need,
308 // with an exception of sorting part, that is added in the end.
310 // However, when we have expenses, we need to do a union with a separate query for expense items from tt_expense_items table.
311 if ($options['show_cost'] && $user->isPluginEnabled('ex')) { // if ex(penses) plugin is enabled
313 $fields = array(); // An array of fields for database query.
314 array_push($fields, 'ei.id');
315 array_push($fields, 'ei.user_id');
316 array_push($fields, '2 as type'); // Type 2 is for tt_expense_items entries.
317 array_push($fields, 'ei.date');
318 if($canViewReports || $isClient)
319 array_push($fields, 'u.name as user');
320 // Add client name if it is selected.
321 if ($options['show_client'] || $grouping_by_client)
322 array_push($fields, 'c.name as client');
323 // Add project name if it is selected.
324 if ($options['show_project'] || $grouping_by_project)
325 array_push($fields, 'p.name as project');
326 if ($options['show_task'] || $grouping_by_task)
327 array_push($fields, 'null'); // null for task name. We need to match column count for union.
328 if ($options['show_custom_field_1'] || $grouping_by_cf_1)
329 array_push($fields, 'null'); // null for cf_1.
330 if ($options['show_start']) {
331 array_push($fields, 'null'); // null for unformatted_start.
332 array_push($fields, 'null'); // null for start.
334 if ($options['show_end'])
335 array_push($fields, 'null'); // null for finish.
336 if ($options['show_duration'])
337 array_push($fields, 'null'); // null for duration.
338 if ($options['show_work_units'])
339 array_push($fields, 'null as units'); // null for work units.
340 // Use the note field to print item name.
341 if ($options['show_note'])
342 array_push($fields, 'ei.name as note');
343 array_push($fields, 'ei.cost as cost');
344 array_push($fields, 'ei.cost as expense');
346 if ($options['show_approved'])
347 array_push($fields, 'ei.approved');
349 if ($canViewReports && $options['show_paid'])
350 array_push($fields, 'ei.paid');
352 if ($canViewReports && $options['show_ip']) {
353 array_push($fields, 'ei.created');
354 array_push($fields, 'ei.created_ip');
355 array_push($fields, 'ei.modified');
356 array_push($fields, 'ei.modified_ip');
358 // Add invoice name if it is selected.
359 if (($canViewReports || $isClient) && $options['show_invoice'])
360 array_push($fields, 'i.name as invoice');
361 if ($options['show_timesheet'])
362 array_push($fields, 'null as timesheet_name');
364 // Prepare sql query part for left joins.
366 if ($canViewReports || $isClient)
367 $left_joins .= " left join tt_users u on (u.id = ei.user_id)";
368 if ($options['show_client'] || $grouping_by_client)
369 $left_joins .= " left join tt_clients c on (c.id = ei.client_id)";
370 if ($options['show_project'] || $grouping_by_project)
371 $left_joins .= " left join tt_projects p on (p.id = ei.project_id)";
372 if (($canViewReports || $isClient) && $options['show_invoice'])
373 $left_joins .= " left join tt_invoices i on (i.id = ei.invoice_id and i.status = 1)";
375 $where = ttReportHelper::getExpenseWhere($options);
377 // Construct sql query for expense items.
378 $sql_for_expense_items = "select ".join(', ', $fields)." from tt_expense_items ei $left_joins $where";
380 // Construct a union.
381 $sql = "($sql) union all ($sql_for_expense_items)";
384 // Determine sort part.
385 $sort_part = ' order by ';
387 $sort_part2 .= ($options['group_by1'] != null && $options['group_by1'] != 'no_grouping') ? ', '.$options['group_by1'] : '';
388 $sort_part2 .= ($options['group_by2'] != null && $options['group_by2'] != 'no_grouping') ? ', '.$options['group_by2'] : '';
389 $sort_part2 .= ($options['group_by3'] != null && $options['group_by3'] != 'no_grouping') ? ', '.$options['group_by3'] : '';
390 if (!$grouping_by_date) $sort_part2 .= ', date';
391 $sort_part .= ltrim($sort_part2, ', '); // Remove leading comma and space.
393 $sort_part .= 'date';
395 if (($canViewReports || $isClient) && $options['users'] && !$grouping_by_user)
396 $sort_part .= ', user, type';
397 if ($options['show_start'])
398 $sort_part .= ', unformatted_start';
399 $sort_part .= ', id';
402 // By now we are ready with sql.
404 // Obtain items for report.
405 $res = $mdb2->query($sql);
406 if (is_a($res, 'PEAR_Error')) die($res->getMessage());
408 while ($val = $res->fetchRow()) {
409 if ($convertTo12Hour) {
410 if($val['start'] != '')
411 $val['start'] = ttTimeHelper::to12HourFormat($val['start']);
412 if($val['finish'] != '')
413 $val['finish'] = ttTimeHelper::to12HourFormat($val['finish']);
415 if (isset($val['cost'])) {
416 if ('.' != $decimalMark)
417 $val['cost'] = str_replace('.', $decimalMark, $val['cost']);
419 if (isset($val['expense'])) {
420 if ('.' != $decimalMark)
421 $val['expense'] = str_replace('.', $decimalMark, $val['expense']);
424 if ($grouping) $val['grouped_by'] = ttReportHelper::makeGroupByKey($options, $val);
425 $val['date'] = ttDateToUserFormat($val['date']);
427 $report_items[] = $val;
430 return $report_items;
433 // putInSession stores tt_log and tt_expense_items ids from a report in user session
434 // as 2 comma-separated lists.
435 static function putInSession($report_items) {
436 unset($_SESSION['report_item_ids']);
437 unset($_SESSION['report_item_expense_ids']);
439 // Iterate through records and build 2 comma-separated lists.
440 foreach($report_items as $item) {
441 if ($item['type'] == 1)
442 $report_item_ids .= ','.$item['id'];
443 else if ($item['type'] == 2)
444 $report_item_expense_ids .= ','.$item['id'];
446 $report_item_ids = trim($report_item_ids, ',');
447 $report_item_expense_ids = trim($report_item_expense_ids, ',');
449 // The lists are reqdy. Put them in session.
450 if ($report_item_ids) $_SESSION['report_item_ids'] = $report_item_ids;
451 if ($report_item_expense_ids) $_SESSION['report_item_expense_ids'] = $report_item_expense_ids;
454 // getFromSession obtains tt_log and tt_expense_items ids stored in user session.
455 static function getFromSession() {
457 $report_item_ids = $_SESSION['report_item_ids'];
458 if ($report_item_ids)
459 $items['report_item_ids'] = explode(',', $report_item_ids);
460 $report_item_expense_ids = $_SESSION['report_item_expense_ids'];
461 if ($report_item_expense_ids)
462 $items['report_item_expense_ids'] = explode(',', $report_item_expense_ids);
466 // getSubtotals calculates report items subtotals when a report is grouped by.
467 // Without expenses, it's a simple select with group by.
468 // With expenses, it becomes a select with group by from a combined set of records obtained with "union all".
469 static function getSubtotals($options) {
471 $mdb2 = getConnection();
473 $concat_part = ttReportHelper::makeConcatPart($options);
474 $work_unit_part = ttReportHelper::makeWorkUnitPart($options);
475 $join_part = ttReportHelper::makeJoinPart($options);
476 $cost_part = ttReportHelper::makeCostPart($options);
477 $where = ttReportHelper::getWhere($options);
478 $group_by_part = ttReportHelper::makeGroupByPart($options);
480 $parts = "$concat_part, sum(time_to_sec(l.duration)) as time, null as expenses".$work_unit_part.$cost_part;
481 $sql = "select $parts from tt_log l $join_part $where $group_by_part";
482 // By now we have sql for time items.
484 // However, when we have expenses, we need to do a union with a separate query for expense items from tt_expense_items table.
485 if ($options['show_cost'] && $user->isPluginEnabled('ex')) { // if ex(penses) plugin is enabled
487 $concat_part = ttReportHelper::makeConcatExpensesPart($options);
488 $join_part = ttReportHelper::makeJoinExpensesPart($options);
489 $where = ttReportHelper::getExpenseWhere($options);
490 $group_by_expenses_part = ttReportHelper::makeGroupByExpensesPart($options);
491 $sql_for_expenses = "select $concat_part, null as time";
492 if ($options['show_work_units']) $sql_for_expenses .= ", null as units";
493 $sql_for_expenses .= ", sum(ei.cost) as cost, sum(ei.cost) as expenses from tt_expense_items ei $join_part $where $group_by_expenses_part";
495 // Create a combined query.
496 $fields = ttReportHelper::makeCombinedSelectPart($options);
497 $combined = "select $fields, sum(time) as time";
498 if ($options['show_work_units']) $combined .= ", sum(units) as units";
499 $combined .= ", sum(cost) as cost, sum(expenses) as expenses from (($sql) union all ($sql_for_expenses)) t group by $fields";
504 $res = $mdb2->query($sql);
505 if (is_a($res, 'PEAR_Error')) die($res->getMessage());
506 while ($val = $res->fetchRow()) {
507 $time = $val['time'] ? sec_to_time_fmt_hm($val['time']) : null;
508 $rowLabel = ttReportHelper::makeGroupByLabel($val['group_field'], $options);
509 if ($options['show_cost']) {
510 $decimalMark = $user->getDecimalMark();
511 if ('.' != $decimalMark) {
512 $val['cost'] = str_replace('.', $decimalMark, $val['cost']);
513 $val['expenses'] = str_replace('.', $decimalMark, $val['expenses']);
515 $subtotals[$val['group_field']] = array('name'=>$rowLabel,'user'=>$val['user'],'project'=>$val['project'],'task'=>$val['task'],'client'=>$val['client'],'cf_1'=>$val['cf_1'],'time'=>$time,'units'=> $val['units'],'cost'=>$val['cost'],'expenses'=>$val['expenses']);
517 $subtotals[$val['group_field']] = array('name'=>$rowLabel,'user'=>$val['user'],'project'=>$val['project'],'task'=>$val['task'],'client'=>$val['client'],'cf_1'=>$val['cf_1'],'time'=>$time, 'units'=> $val['units']);
523 // getTotals calculates total hours and cost for all report items.
524 static function getTotals($options)
527 $mdb2 = getConnection();
529 $trackingMode = $user->getTrackingMode();
530 $decimalMark = $user->getDecimalMark();
531 $where = ttReportHelper::getWhere($options);
534 $time_part = "sum(time_to_sec(l.duration)) as time";
535 if ($options['show_work_units']) {
536 $unitTotalsOnly = $user->getConfigOption('unit_totals_only');
537 $firstUnitThreshold = $user->getConfigInt('1st_unit_threshold', 0);
538 $minutesInUnit = $user->getConfigInt('minutes_in_unit', 15);
539 $units_part = $unitTotalsOnly ? ", null as units" : ", sum(if(l.billable = 0 or time_to_sec(l.duration)/60 < $firstUnitThreshold, 0, ceil(time_to_sec(l.duration)/60/$minutesInUnit))) as units";
541 if ($options['show_cost']) {
542 if (MODE_TIME == $trackingMode)
543 $cost_part = ", sum(cast(l.billable * coalesce(u.rate, 0) * time_to_sec(l.duration)/3600 as decimal(10,2))) as cost, null as expenses";
545 $cost_part = ", sum(cast(l.billable * coalesce(upb.rate, 0) * time_to_sec(l.duration)/3600 as decimal(10,2))) as cost, null as expenses";
547 $cost_part = ", null as cost, null as expenses";
549 if ($options['show_cost']) {
550 if (MODE_TIME == $trackingMode) {
551 $left_joins = "left join tt_users u on (l.user_id = u.id)";
553 $left_joins = "left join tt_user_project_binds upb on (l.user_id = upb.user_id and l.project_id = upb.project_id)";
556 // Prepare sql query part for inner joins.
558 if ($user->isPluginEnabled('ts') && $options['timesheet']) {
559 $timesheet_option = $options['timesheet'];
560 if ($timesheet_option == TIMESHEET_PENDING)
561 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.submit_status = 1 and ts.approve_status is null)";
562 else if ($timesheet_option == TIMESHEET_APPROVED)
563 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.approve_status = 1)";
564 else if ($timesheet_option == TIMESHEET_NOT_APPROVED)
565 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.approve_status = 0)";
567 // Prepare a query for time items.
568 $sql = "select $time_part $units_part $cost_part from tt_log l $left_joins $inner_joins $where";
570 // If we have expenses, query becomes a bit more complex.
571 if ($options['show_cost'] && $user->isPluginEnabled('ex')) {
572 $where = ttReportHelper::getExpenseWhere($options);
573 $sql_for_expenses = "select null as time";
574 if ($options['show_work_units']) $sql_for_expenses .= ", null as units";
575 $sql_for_expenses .= ", sum(cost) as cost, sum(cost) as expenses from tt_expense_items ei $where";
577 // Create a combined query.
578 $combined = "select sum(time) as time";
579 if ($options['show_work_units']) $combined .= ", sum(units) as units";
580 $combined .= ", sum(cost) as cost, sum(expenses) as expenses from (($sql) union all ($sql_for_expenses)) t";
585 $res = $mdb2->query($sql);
586 if (is_a($res, 'PEAR_Error')) die($res->getMessage());
588 $val = $res->fetchRow();
589 $total_time = $val['time'] ? sec_to_time_fmt_hm($val['time']) : null;
590 if ($options['show_cost']) {
591 $total_cost = $val['cost'];
592 if (!$total_cost) $total_cost = '0.00';
593 if ('.' != $decimalMark)
594 $total_cost = str_replace('.', $decimalMark, $total_cost);
595 $total_expenses = $val['expenses'];
596 if (!$total_expenses) $total_expenses = '0.00';
597 if ('.' != $decimalMark)
598 $total_expenses = str_replace('.', $decimalMark, $total_expenses);
601 $dateFormat = $user->getDateFormat();
602 if ($options['period'])
603 $period = new Period($options['period'], new DateAndTime($dateFormat));
605 $period = new Period();
607 new DateAndTime($dateFormat, $options['period_start']),
608 new DateAndTime($dateFormat, $options['period_end']));
611 $totals['start_date'] = $period->getStartDate();
612 $totals['end_date'] = $period->getEndDate();
613 $totals['time'] = $total_time;
614 $totals['units'] = $val['units'];
615 $totals['cost'] = $total_cost;
616 $totals['expenses'] = $total_expenses;
621 // The assignToInvoice assigns a set of records to a specific invoice.
622 static function assignToInvoice($invoice_id, $time_log_ids, $expense_item_ids) {
624 $mdb2 = getConnection();
626 $group_id = $user->getGroup();
627 $org_id = $user->org_id;
630 $sql = "update tt_log set invoice_id = ".$mdb2->quote($invoice_id).
631 " where id in(".join(', ', $time_log_ids).") and group_id = $group_id and org_id = $org_id";
632 $affected = $mdb2->exec($sql);
633 if (is_a($affected, 'PEAR_Error')) die($affected->getMessage());
635 if ($expense_item_ids) {
636 $sql = "update tt_expense_items set invoice_id = ".$mdb2->quote($invoice_id).
637 " where id in(".join(', ', $expense_item_ids).") and group_id = $group_id and org_id = $org_id";
638 $affected = $mdb2->exec($sql);
639 if (is_a($affected, 'PEAR_Error')) die($affected->getMessage());
643 // The assignToTimesheet assigns a set of tt_log records to a specific timesheet.
644 static function assignToTimesheet($timesheet_id, $time_log_ids) {
646 $mdb2 = getConnection();
648 $user_id = $user->getUser();
649 $group_id = $user->getGroup();
650 $org_id = $user->org_id;
653 // Use inner join as a protection mechanism not to do anything with "acted upon" timesheets.
654 // Allow oprations only with pending timesheets.
656 // Assigning a timesheet to records.
657 $inner_join = " inner join tt_timesheets ts on (ts.id = $timesheet_id".
658 " and ts.user_id = $user_id and ts.approve_status is null". // Timesheet to assign to is pending.
659 // Part below: existing timesheet either not exists or is also pending.
660 " and (l.timesheet_id is null or (l.timesheet_id = ts.id and ts.approve_status is null)))";
662 $inner_join = " inner join tt_timesheets ts on (ts.id = l.timesheet_id".
663 " and ts.user_id = $user_id and ts.approve_status is null)"; // Do not deassign from acted-upon timesheets.
666 $sql = "update tt_log l $inner_join".
667 " set l.timesheet_id = ".$mdb2->quote($timesheet_id).
668 " where l.id in(".join(', ', $time_log_ids).") and l.user_id = $user_id and l.group_id = $group_id and l.org_id = $org_id";
669 $affected = $mdb2->exec($sql);
670 if (is_a($affected, 'PEAR_Error')) die($affected->getMessage());
674 // The markApproved marks a set of records as either approved or unapproved.
675 static function markApproved($time_log_ids, $expense_item_ids, $approved = true) {
677 $mdb2 = getConnection();
679 $group_id = $user->getGroup();
680 $org_id = $user->org_id;
682 $approved_val = (int) $approved;
684 $sql = "update tt_log set approved = $approved_val".
685 " where id in(".join(', ', $time_log_ids).") and group_id = $group_id and org_id = $org_id";
686 $affected = $mdb2->exec($sql);
687 if (is_a($affected, 'PEAR_Error')) die($affected->getMessage());
689 if ($expense_item_ids) {
690 $sql = "update tt_expense_items set approved = $approved_val".
691 " where id in(".join(', ', $expense_item_ids).") and group_id = $group_id and org_id = $org_id";
692 $affected = $mdb2->exec($sql);
693 if (is_a($affected, 'PEAR_Error')) die($affected->getMessage());
697 // The markPaid marks a set of records as either paid or unpaid.
698 static function markPaid($time_log_ids, $expense_item_ids, $paid = true) {
700 $mdb2 = getConnection();
702 $group_id = $user->getGroup();
703 $org_id = $user->org_id;
705 $paid_val = (int) $paid;
707 $sql = "update tt_log set paid = $paid_val".
708 " where id in(".join(', ', $time_log_ids).") and group_id = $group_id and org_id = $org_id";
709 $affected = $mdb2->exec($sql);
710 if (is_a($affected, 'PEAR_Error')) die($affected->getMessage());
712 if ($expense_item_ids) {
713 $sql = "update tt_expense_items set paid = $paid_val".
714 " where id in(".join(', ', $expense_item_ids).") and group_id = $group_id and org_id = $org_id";
715 $affected = $mdb2->exec($sql);
716 if (is_a($affected, 'PEAR_Error')) die($affected->getMessage());
720 // prepareReportBody - prepares an email body for report.
721 static function prepareReportBody($options, $comment = null)
726 // Determine these once as they are used in multiple places in this function.
727 $canViewReports = $user->can('view_reports') || $user->can('view_all_reports');
728 $isClient = $user->isClient();
730 $items = ttReportHelper::getItems($options);
731 $grouping = ttReportHelper::grouping($options);
733 $subtotals = ttReportHelper::getSubtotals($options);
734 $totals = ttReportHelper::getTotals($options);
736 // Use custom fields plugin if it is enabled.
737 if ($user->isPluginEnabled('cf'))
738 $custom_fields = new CustomFields();
740 // Define some styles to use in email.
741 $style_title = 'text-align: center; font-size: 15pt; font-family: Arial, Helvetica, sans-serif;';
742 $tableHeader = 'font-weight: bold; background-color: #a6ccf7; text-align: left;';
743 $tableHeaderCentered = 'font-weight: bold; background-color: #a6ccf7; text-align: center;';
744 $rowItem = 'background-color: #ffffff;';
745 $rowItemAlt = 'background-color: #f5f5f5;';
746 $rowSubtotal = 'background-color: #e0e0e0;';
747 $cellLeftAligned = 'text-align: left; vertical-align: top;';
748 $cellRightAligned = 'text-align: right; vertical-align: top;';
749 $cellLeftAlignedSubtotal = 'font-weight: bold; text-align: left; vertical-align: top;';
750 $cellRightAlignedSubtotal = 'font-weight: bold; text-align: right; vertical-align: top;';
752 // Determine column span for note field.
754 if ($user->can('view_reports') || $user->can('view_all_reports') || $user->isClient()) $colspan++;
755 if ($options['show_client']) $colspan++;
756 if ($options['show_project']) $colspan++;
757 if ($options['show_task']) $colspan++;
758 if ($options['show_custom_field_1']) $colspan++;
759 if ($options['show_start']) $colspan++;
760 if ($options['show_end']) $colspan++;
761 if ($options['show_duration']) $colspan++;
762 if ($options['show_work_units']) $colspan++;
763 if ($options['show_cost']) $colspan++;
764 if ($options['show_approved']) $colspan++;
765 if ($options['show_paid']) $colspan++;
766 if ($options['show_ip']) $colspan++;
767 if ($options['show_invoice']) $colspan++;
768 if ($options['show_timesheet']) $colspan++;
770 // Start creating email body.
772 $body .= '<head><meta http-equiv="content-type" content="text/html; charset='.CHARSET.'"></head>';
776 $body .= '<p style="'.$style_title.'">'.$i18n->get('form.mail.report_subject').': '.$totals['start_date'].' - '.$totals['end_date'].'</p>';
779 if ($comment) $body .= '<p>'.htmlspecialchars($comment).'</p>';
781 if ($options['show_totals_only']) {
782 // Totals only report. Output subtotals.
783 $group_by_header = ttReportHelper::makeGroupByHeader($options);
785 $body .= '<table border="0" cellpadding="4" cellspacing="0" width="100%">';
787 $body .= '<td style="'.$tableHeader.'">'.$group_by_header.'</td>';
788 if ($options['show_duration'])
789 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.duration').'</td>';
790 if ($options['show_work_units'])
791 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.work_units_short').'</td>';
792 if ($options['show_cost'])
793 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.cost').'</td>';
795 foreach($subtotals as $subtotal) {
796 $body .= '<tr style="'.$rowSubtotal.'">';
797 $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.($subtotal['name'] ? htmlspecialchars($subtotal['name']) : ' ').'</td>';
798 if ($options['show_duration']) {
799 $body .= '<td style="'.$cellRightAlignedSubtotal.'">';
800 if ($subtotal['time'] <> '0:00') $body .= $subtotal['time'];
803 if ($options['show_work_units']) {
804 $body .= '<td style="'.$cellRightAlignedSubtotal.'">';
805 $body .= $subtotal['units'];
808 if ($options['show_cost']) {
809 $body .= '<td style="'.$cellRightAlignedSubtotal.'">';
810 $body .= ($canViewReports || $isClient) ? $subtotal['cost'] : $subtotal['expenses'];
817 $body .= '<tr><td> </td></tr>';
818 $body .= '<tr style="'.$rowSubtotal.'">';
819 $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$i18n->get('label.total').'</td>';
820 if ($options['show_duration']) {
821 $body .= '<td style="'.$cellRightAlignedSubtotal.'">';
822 if ($totals['time'] <> '0:00') $body .= $totals['time'];
825 if ($options['show_work_units']) {
826 $body .= '<td style="'.$cellRightAlignedSubtotal.'">';
827 $body .= $totals['units'];
830 if ($options['show_cost']) {
831 $body .= '<td nowrap style="'.$cellRightAlignedSubtotal.'">'.htmlspecialchars($user->currency).' ';
832 $body .= ($canViewReports || $isClient) ? $totals['cost'] : $totals['expenses'];
841 // Print table header.
842 $body .= '<table border="0" cellpadding="4" cellspacing="0" width="100%">';
844 $body .= '<td style="'.$tableHeader.'">'.$i18n->get('label.date').'</td>';
845 if ($canViewReports || $isClient)
846 $body .= '<td style="'.$tableHeader.'">'.$i18n->get('label.user').'</td>';
847 if ($options['show_client'])
848 $body .= '<td style="'.$tableHeader.'">'.$i18n->get('label.client').'</td>';
849 if ($options['show_project'])
850 $body .= '<td style="'.$tableHeader.'">'.$i18n->get('label.project').'</td>';
851 if ($options['show_task'])
852 $body .= '<td style="'.$tableHeader.'">'.$i18n->get('label.task').'</td>';
853 if ($options['show_custom_field_1'])
854 $body .= '<td style="'.$tableHeader.'">'.htmlspecialchars($custom_fields->fields[0]['label']).'</td>';
855 if ($options['show_start'])
856 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.start').'</td>';
857 if ($options['show_end'])
858 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.finish').'</td>';
859 if ($options['show_duration'])
860 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.duration').'</td>';
861 if ($options['show_work_units'])
862 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.work_units_short').'</td>';
863 if ($options['show_cost'])
864 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.cost').'</td>';
865 if ($options['show_approved'])
866 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.approved').'</td>';
867 if ($options['show_paid'])
868 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.paid').'</td>';
869 if ($options['show_ip'])
870 $body .= '<td style="'.$tableHeaderCentered.'" width="5%">'.$i18n->get('label.ip').'</td>';
871 if ($options['show_invoice'])
872 $body .= '<td style="'.$tableHeader.'">'.$i18n->get('label.invoice').'</td>';
873 if ($options['show_timesheet'])
874 $body .= '<td style="'.$tableHeader.'">'.$i18n->get('label.timesheet').'</td>';
877 // Initialize variables to print subtotals.
878 if ($items && $grouping) {
879 $print_subtotals = true;
881 $prev_grouped_by = '';
882 $cur_grouped_by = '';
884 // Initialize variables to alternate color of rows for different dates.
887 $row_style = $rowItem;
889 // Print report items.
890 if (is_array($items)) {
891 foreach ($items as $record) {
892 $cur_date = $record['date'];
893 // Print a subtotal row after a block of grouped items.
894 if ($print_subtotals) {
895 $cur_grouped_by = $record['grouped_by'];
896 if ($cur_grouped_by != $prev_grouped_by && !$first_pass) {
897 $body .= '<tr style="'.$rowSubtotal.'">';
898 $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$i18n->get('label.subtotal').'</td>';
899 $subtotal_name = htmlspecialchars($subtotals[$prev_grouped_by]['name']);
900 if ($canViewReports || $isClient) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['user'].'</td>';
901 if ($options['show_client']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['client'].'</td>';
902 if ($options['show_project']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['project'].'</td>';
903 if ($options['show_task']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['task'].'</td>';
904 if ($options['show_custom_field_1']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['cf_1'].'</td>';
905 if ($options['show_start']) $body .= '<td></td>';
906 if ($options['show_end']) $body .= '<td></td>';
907 if ($options['show_duration']) $body .= '<td style="'.$cellRightAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['time'].'</td>';
908 if ($options['show_work_units']) $body .= '<td style="'.$cellRightAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['units'].'</td>';
909 if ($options['show_cost']) {
910 $body .= '<td style="'.$cellRightAlignedSubtotal.'">';
911 $body .= ($canViewReports || $isClient) ? $subtotals[$prev_grouped_by]['cost'] : $subtotals[$prev_grouped_by]['expenses'];
914 if ($options['show_approved']) $body .= '<td></td>';
915 if ($options['show_paid']) $body .= '<td></td>';
916 if ($options['show_ip']) $body .= '<td></td>';
917 if ($options['show_invoice']) $body .= '<td></td>';
918 if ($options['show_timesheet']) $body .= '<td></td>';
920 $body .= '<tr><td> </td></tr>';
925 // Print a regular row.
926 if ($cur_date != $prev_date)
927 $row_style = ($row_style == $rowItem) ? $rowItemAlt : $rowItem;
928 $body .= '<tr style="'.$row_style.'">';
929 $body .= '<td style="'.$cellLeftAligned.'">'.$record['date'].'</td>';
930 if ($canViewReports || $isClient)
931 $body .= '<td style="'.$cellLeftAligned.'">'.htmlspecialchars($record['user']).'</td>';
932 if ($options['show_client'])
933 $body .= '<td style="'.$cellLeftAligned.'">'.htmlspecialchars($record['client']).'</td>';
934 if ($options['show_project'])
935 $body .= '<td style="'.$cellLeftAligned.'">'.htmlspecialchars($record['project']).'</td>';
936 if ($options['show_task'])
937 $body .= '<td style="'.$cellLeftAligned.'">'.htmlspecialchars($record['task']).'</td>';
938 if ($options['show_custom_field_1'])
939 $body .= '<td style="'.$cellLeftAligned.'">'.htmlspecialchars($record['cf_1']).'</td>';
940 if ($options['show_start'])
941 $body .= '<td nowrap style="'.$cellRightAligned.'">'.$record['start'].'</td>';
942 if ($options['show_end'])
943 $body .= '<td nowrap style="'.$cellRightAligned.'">'.$record['finish'].'</td>';
944 if ($options['show_duration'])
945 $body .= '<td style="'.$cellRightAligned.'">'.$record['duration'].'</td>';
946 if ($options['show_work_units'])
947 $body .= '<td style="'.$cellRightAligned.'">'.$record['units'].'</td>';
948 if ($options['show_cost'])
949 $body .= '<td style="'.$cellRightAligned.'">'.$record['cost'].'</td>';
950 if ($options['show_approved']) {
951 $body .= '<td style="'.$cellRightAligned.'">';
952 $body .= $record['approved'] == 1 ? $i18n->get('label.yes') : $i18n->get('label.no');
955 if ($options['show_paid']) {
956 $body .= '<td style="'.$cellRightAligned.'">';
957 $body .= $record['paid'] == 1 ? $i18n->get('label.yes') : $i18n->get('label.no');
960 if ($options['show_ip']) {
961 $body .= '<td style="'.$cellRightAligned.'">';
962 $body .= $record['modified'] ? $record['modified_ip'].' '.$record['modified'] : $record['created_ip'].' '.$record['created'];
965 if ($options['show_invoice'])
966 $body .= '<td style="'.$cellRightAligned.'">'.htmlspecialchars($record['invoice']).'</td>';
967 if ($options['show_timesheet'])
968 $body .= '<td style="'.$cellRightAligned.'">'.htmlspecialchars($record['timesheet']).'</td>';
970 if ($options['show_note'] && $record['note']) {
971 $body .= '<tr style="'.$row_style.'">';
972 $body .= '<td style="'.$cellRightAligned.'">'.$i18n->get('label.note').':</td>';
973 $body .= '<td colspan="'.$colspan.'">'.$record['note'].'</td>';
976 $prev_date = $record['date'];
977 if ($print_subtotals)
978 $prev_grouped_by = $record['grouped_by'];
982 // Print a terminating subtotal.
983 if ($print_subtotals) {
984 $body .= '<tr style="'.$rowSubtotal.'">';
985 $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$i18n->get('label.subtotal').'</td>';
986 $subtotal_name = htmlspecialchars($subtotals[$cur_grouped_by]['name']);
987 if ($canViewReports || $isClient) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['user'].'</td>';
988 if ($options['show_client']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['client'].'</td>';
989 if ($options['show_project']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['project'].'</td>';
990 if ($options['show_task']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['task'].'</td>';
991 if ($options['show_custom_field_1']) $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$subtotals[$prev_grouped_by]['cf_1'].'</td>';
992 if ($options['show_start']) $body .= '<td></td>';
993 if ($options['show_end']) $body .= '<td></td>';
994 if ($options['show_duration']) $body .= '<td style="'.$cellRightAlignedSubtotal.'">'.$subtotals[$cur_grouped_by]['time'].'</td>';
995 if ($options['show_work_units']) $body .= '<td style="'.$cellRightAlignedSubtotal.'">'.$subtotals[$cur_grouped_by]['units'].'</td>';
996 if ($options['show_cost']) {
997 $body .= '<td style="'.$cellRightAlignedSubtotal.'">';
998 $body .= ($canViewReports || $isClient) ? $subtotals[$cur_grouped_by]['cost'] : $subtotals[$cur_grouped_by]['expenses'];
1001 if ($options['show_approved']) $body .= '<td></td>';
1002 if ($options['show_paid']) $body .= '<td></td>';
1003 if ($options['show_ip']) $body .= '<td></td>';
1004 if ($options['show_invoice']) $body .= '<td></td>';
1005 if ($options['show_timesheet']) $body .= '<td></td>';
1010 $body .= '<tr><td> </td></tr>';
1011 $body .= '<tr style="'.$rowSubtotal.'">';
1012 $body .= '<td style="'.$cellLeftAlignedSubtotal.'">'.$i18n->get('label.total').'</td>';
1013 if ($canViewReports || $isClient) $body .= '<td></td>';
1014 if ($options['show_client']) $body .= '<td></td>';
1015 if ($options['show_project']) $body .= '<td></td>';
1016 if ($options['show_task']) $body .= '<td></td>';
1017 if ($options['show_custom_field_1']) $body .= '<td></td>';
1018 if ($options['show_start']) $body .= '<td></td>';
1019 if ($options['show_end']) $body .= '<td></td>';
1020 if ($options['show_duration']) $body .= '<td style="'.$cellRightAlignedSubtotal.'">'.$totals['time'].'</td>';
1021 if ($options['show_work_units']) $body .= '<td style="'.$cellRightAlignedSubtotal.'">'.$totals['units'].'</td>';
1022 if ($options['show_cost']) {
1023 $body .= '<td nowrap style="'.$cellRightAlignedSubtotal.'">'.htmlspecialchars($user->currency).' ';
1024 $body .= ($canViewReports || $isClient) ? $totals['cost'] : $totals['expenses'];
1027 if ($options['show_approved']) $body .= '<td></td>';
1028 if ($options['show_paid']) $body .= '<td></td>';
1029 if ($options['show_ip']) $body .= '<td></td>';
1030 if ($options['show_invoice']) $body .= '<td></td>';
1031 if ($options['show_timesheet']) $body .= '<td></td>';
1034 $body .= '</table>';
1038 if (!defined('REPORT_FOOTER') || !(REPORT_FOOTER == false))
1039 $body .= '<p style="text-align: center;">'.$i18n->get('form.mail.footer').'</p>';
1041 // Finish creating email body.
1042 $body .= '</body></html>';
1047 // checkFavReportCondition - checks whether it is okay to send fav report.
1048 static function checkFavReportCondition($options, $condition)
1050 $items = ttReportHelper::getItems($options);
1052 $condition = trim(str_replace('count', '', $condition));
1054 $greater_or_equal = ttStartsWith($condition, '>=');
1055 if ($greater_or_equal) $condition = trim(str_replace('>=', '', $condition));
1057 $less_or_equal = ttStartsWith($condition, '<=');
1058 if ($less_or_equal) $condition = trim(str_replace('<=', '', $condition));
1060 $not_equal = ttStartsWith($condition, '<>');
1061 if ($not_equal) $condition = trim(str_replace('<>', '', $condition));
1063 $greater = ttStartsWith($condition, '>');
1064 if ($greater) $condition = trim(str_replace('>', '', $condition));
1066 $less = ttStartsWith($condition, '<');
1067 if ($less) $condition = trim(str_replace('<', '', $condition));
1069 $equal = ttStartsWith($condition, '=');
1070 if ($equal) $condition = trim(str_replace('=', '', $condition));
1072 $count_required = (int) $condition;
1074 if ($greater && count($items) > $count_required) return true;
1075 if ($greater_or_equal && count($items) >= $count_required) return true;
1076 if ($less && count($items) < $count_required) return true;
1077 if ($less_or_equal && count($items) <= $count_required) return true;
1078 if ($equal && count($items) == $count_required) return true;
1079 if ($not_equal && count($items) <> $count_required) return true;
1084 // sendFavReport - sends a favorite report to a specified email, called from cron.php
1085 static function sendFavReport($options, $subject, $email, $cc) {
1086 // We are called from cron.php, we have no $bean in session.
1087 // cron.php sets global $user and $i18n objects to match our favorite report user.
1091 // Prepare report body.
1092 $body = ttReportHelper::prepareReportBody($options);
1094 import('mail.Mailer');
1095 $mailer = new Mailer();
1096 $mailer->setCharSet(CHARSET);
1097 $mailer->setContentType('text/html');
1098 $mailer->setSender(SENDER);
1100 $mailer->setReceiverCC($cc);
1101 if (!empty($user->bcc_email))
1102 $mailer->setReceiverBCC($user->bcc_email);
1103 $mailer->setReceiver($email);
1104 $mailer->setMailMode(MAIL_MODE);
1105 if (empty($subject)) $subject = $options['name'];
1106 if (!$mailer->send($subject, $body))
1112 // getReportOptions - returns an array of report options constructed from session bean.
1114 // Note: similarly to ttFavReportHelper::getReportOptions, this function is a part of
1115 // refactoring to simplify maintenance of report generating functions, as we currently
1116 // have 2 sets: normal reporting (from bean), and fav report emailing (from db fields).
1117 // Using options obtained from either db or bean shall allow us to use only one set of functions.
1118 static function getReportOptions($bean) {
1121 // Prepare an array of report options.
1124 // Construct one by one.
1125 $options['name'] = null; // No name required.
1126 $options['user_id'] = $user->id; // Not sure if we need user_id here. Fav reports use it to recycle $user object in cron.php.
1127 $options['client_id'] = $bean->getAttribute('client');
1128 $options['cf_1_option_id'] = $bean->getAttribute('option');
1129 $options['project_id'] = $bean->getAttribute('project');
1130 $options['task_id'] = $bean->getAttribute('task');
1131 $options['billable'] = $bean->getAttribute('include_records');
1132 $options['invoice'] = $bean->getAttribute('invoice');
1133 $options['paid_status'] = $bean->getAttribute('paid_status');
1134 $options['approved'] = $bean->getAttribute('approved');
1135 if ($user->isPluginEnabled('ap') && $user->isClient() && !$user->can('view_client_unapproved'))
1136 $options['approved'] = 1; // Restrict clients to approved records only.
1137 $options['timesheet'] = $bean->getAttribute('timesheet');
1138 if (is_array($bean->getAttribute('users'))) $options['users'] = join(',', $bean->getAttribute('users'));
1139 $options['period'] = $bean->getAttribute('period');
1140 $options['period_start'] = $bean->getAttribute('start_date');
1141 $options['period_end'] = $bean->getAttribute('end_date');
1142 $options['show_client'] = $bean->getAttribute('chclient');
1143 $options['show_invoice'] = $bean->getAttribute('chinvoice');
1144 $options['show_approved'] = $bean->getAttribute('chapproved');
1145 $options['show_paid'] = $bean->getAttribute('chpaid');
1146 $options['show_ip'] = $bean->getAttribute('chip');
1147 $options['show_project'] = $bean->getAttribute('chproject');
1148 $options['show_start'] = $bean->getAttribute('chstart');
1149 $options['show_duration'] = $bean->getAttribute('chduration');
1150 $options['show_cost'] = $bean->getAttribute('chcost');
1151 $options['show_task'] = $bean->getAttribute('chtask');
1152 $options['show_end'] = $bean->getAttribute('chfinish');
1153 $options['show_note'] = $bean->getAttribute('chnote');
1154 $options['show_custom_field_1'] = $bean->getAttribute('chcf_1');
1155 $options['show_work_units'] = $bean->getAttribute('chunits');
1156 $options['show_timesheet'] = $bean->getAttribute('chtimesheet');
1157 $options['show_files'] = $bean->getAttribute('chfiles');
1158 $options['show_totals_only'] = $bean->getAttribute('chtotalsonly');
1159 $options['group_by1'] = $bean->getAttribute('group_by1');
1160 $options['group_by2'] = $bean->getAttribute('group_by2');
1161 $options['group_by3'] = $bean->getAttribute('group_by3');
1165 // verifyBean is a security function to make sure data in bean makes sense for a group.
1166 static function verifyBean($bean) {
1170 $users_in_bean = $bean->getAttribute('users');
1171 if (is_array($users_in_bean)) {
1172 $users_in_group = ttGroupHelper::getUsers();
1173 foreach ($users_in_group as $user_in_group) {
1174 $valid_ids[] = $user_in_group['id'];
1176 foreach ($users_in_bean as $user_in_bean) {
1177 if (!in_array($user_in_bean, $valid_ids)) {
1183 // TODO: add additional checks here. Perhaps do it before saving the bean for consistency.
1187 // makeGroupByKey builds a combined group by key from group_by1, group_by2 and group_by3 values
1188 // (passed in $options) and a row of data ($row obtained from a db query).
1189 static function makeGroupByKey($options, $row) {
1190 if ($options['group_by1'] != null && $options['group_by1'] != 'no_grouping') {
1191 // We have group_by1.
1192 $group_by1 = $options['group_by1'];
1193 $group_by1_value = $row[$group_by1];
1194 //if ($group_by1 == 'date') $group_by1_value = ttDateToUserFormat($group_by1_value);
1195 if (empty($group_by1_value)) $group_by1_value = 'Null'; // To match what comes out of makeConcatPart.
1196 $group_by_key .= ' - '.$group_by1_value;
1198 if ($options['group_by2'] != null && $options['group_by2'] != 'no_grouping') {
1199 // We have group_by2.
1200 $group_by2 = $options['group_by2'];
1201 $group_by2_value = $row[$group_by2];
1202 //if ($group_by2 == 'date') $group_by2_value = ttDateToUserFormat($group_by2_value);
1203 if (empty($group_by2_value)) $group_by2_value = 'Null'; // To match what comes out of makeConcatPart.
1204 $group_by_key .= ' - '.$group_by2_value;
1206 if ($options['group_by3'] != null && $options['group_by3'] != 'no_grouping') {
1207 // We have group_by3.
1208 $group_by3 = $options['group_by3'];
1209 $group_by3_value = $row[$group_by3];
1210 //if ($group_by3 == 'date') $group_by3_value = ttDateToUserFormat($group_by3_value);
1211 if (empty($group_by3_value)) $group_by3_value = 'Null'; // To match what comes out of makeConcatPart.
1212 $group_by_key .= ' - '.$group_by3_value;
1214 $group_by_key = trim($group_by_key, ' -');
1215 return $group_by_key;
1218 // makeGroupByPart builds a combined group by part for sql query for time items using group_by1,
1219 // group_by2, and group_by3 values passed in $options.
1220 static function makeGroupByPart($options) {
1221 if (!ttReportHelper::grouping($options)) return null;
1223 $group_by1 = $options['group_by1'];
1224 $group_by2 = $options['group_by2'];
1225 $group_by3 = $options['group_by3'];
1227 switch ($group_by1) {
1229 $group_by_parts .= ', l.date';
1232 $group_by_parts .= ', u.name';
1235 $group_by_parts .= ', c.name';
1238 $group_by_parts .= ', p.name';
1241 $group_by_parts .= ', t.name';
1244 $group_by_parts .= ', cfo.value';
1247 switch ($group_by2) {
1249 $group_by_parts .= ', l.date';
1252 $group_by_parts .= ', u.name';
1255 $group_by_parts .= ', c.name';
1258 $group_by_parts .= ', p.name';
1261 $group_by_parts .= ', t.name';
1264 $group_by_parts .= ', cfo.value';
1267 switch ($group_by3) {
1269 $group_by_parts .= ', l.date';
1272 $group_by_parts .= ', u.name';
1275 $group_by_parts .= ', c.name';
1278 $group_by_parts .= ', p.name';
1281 $group_by_parts .= ', t.name';
1284 $group_by_parts .= ', cfo.value';
1287 // Remove garbage from the beginning.
1288 $group_by_parts = ltrim($group_by_parts, ', ');
1289 $group_by_part = "group by $group_by_parts";
1290 return $group_by_part;
1293 // makeGroupByExpensesPart builds a combined group by part for sql query for expense items using
1294 // group_by1, group_by2, and group_by3 values passed in $options.
1295 static function makeGroupByExpensesPart($options) {
1296 $no_grouping = ($options['group_by1'] == null || $options['group_by1'] == 'no_grouping') &&
1297 ($options['group_by2'] == null || $options['group_by2'] == 'no_grouping') &&
1298 ($options['group_by3'] == null || $options['group_by3'] == 'no_grouping');
1299 if ($no_grouping) return null;
1301 $group_by1 = $options['group_by1'];
1302 $group_by2 = $options['group_by2'];
1303 $group_by3 = $options['group_by3'];
1305 switch ($group_by1) {
1307 $group_by_parts .= ', ei.date';
1310 $group_by_parts .= ', u.name';
1313 $group_by_parts .= ', c.name';
1316 $group_by_parts .= ', p.name';
1319 switch ($group_by2) {
1321 $group_by_parts .= ', ei.date';
1324 $group_by_parts .= ', u.name';
1327 $group_by_parts .= ', c.name';
1330 $group_by_parts .= ', p.name';
1333 switch ($group_by3) {
1335 $group_by_parts .= ', ei.date';
1338 $group_by_parts .= ', u.name';
1341 $group_by_parts .= ', c.name';
1344 $group_by_parts .= ', p.name';
1347 // Remove garbage from the beginning.
1348 $group_by_parts = ltrim($group_by_parts, ', ');
1349 if ($group_by_parts)
1350 $group_by_part = "group by $group_by_parts";
1351 return $group_by_part;
1354 // makeConcatPart builds a concatenation part for getSubtotals query (for time items).
1355 static function makeConcatPart($options) {
1356 $group_by1 = $options['group_by1'];
1357 $group_by2 = $options['group_by2'];
1358 $group_by3 = $options['group_by3'];
1360 switch ($group_by1) {
1362 $what_to_concat .= ", ' - ', l.date";
1365 $what_to_concat .= ", ' - ', u.name";
1366 $fields_part .= ', u.name as user';
1369 $what_to_concat .= ", ' - ', coalesce(c.name, 'Null')";
1370 $fields_part .= ', c.name as client';
1373 $what_to_concat .= ", ' - ', coalesce(p.name, 'Null')";
1374 $fields_part .= ', p.name as project';
1377 $what_to_concat .= ", ' - ', coalesce(t.name, 'Null')";
1378 $fields_part .= ', t.name as task';
1381 $what_to_concat .= ", ' - ', coalesce(cfo.value, 'Null')";
1382 $fields_part .= ', cfo.value as cf_1';
1385 switch ($group_by2) {
1387 $what_to_concat .= ", ' - ', l.date";
1390 $what_to_concat .= ", ' - ', u.name";
1391 $fields_part .= ', u.name as user';
1394 $what_to_concat .= ", ' - ', coalesce(c.name, 'Null')";
1395 $fields_part .= ', c.name as client';
1398 $what_to_concat .= ", ' - ', coalesce(p.name, 'Null')";
1399 $fields_part .= ', p.name as project';
1402 $what_to_concat .= ", ' - ', coalesce(t.name, 'Null')";
1403 $fields_part .= ', t.name as task';
1406 $what_to_concat .= ", ' - ', coalesce(cfo.value, 'Null')";
1407 $fields_part .= ', cfo.value as cf_1';
1410 switch ($group_by3) {
1412 $what_to_concat .= ", ' - ', l.date";
1415 $what_to_concat .= ", ' - ', u.name";
1416 $fields_part .= ', u.name as user';
1419 $what_to_concat .= ", ' - ', coalesce(c.name, 'Null')";
1420 $fields_part .= ', c.name as client';
1423 $what_to_concat .= ", ' - ', coalesce(p.name, 'Null')";
1424 $fields_part .= ', p.name as project';
1427 $what_to_concat .= ", ' - ', coalesce(t.name, 'Null')";
1428 $fields_part .= ', t.name as task';
1431 $what_to_concat .= ", ' - ', coalesce(cfo.value, 'Null')";
1432 $fields_part .= ', cfo.value as cf_1';
1435 // Remove garbage from both ends.
1436 $what_to_concat = trim($what_to_concat, "', -");
1437 $concat_part = "concat($what_to_concat) as group_field";
1438 $concat_part = trim($concat_part, ' -');
1439 return "$concat_part $fields_part";
1442 // makeConcatPart builds a concatenation part for getSubtotals query (for expense items).
1443 static function makeConcatExpensesPart($options) {
1444 $group_by1 = $options['group_by1'];
1445 $group_by2 = $options['group_by2'];
1446 $group_by3 = $options['group_by3'];
1448 switch ($group_by1) {
1450 $what_to_concat .= ", ' - ', ei.date";
1453 $what_to_concat .= ", ' - ', u.name";
1454 $fields_part .= ', u.name as user';
1457 $what_to_concat .= ", ' - ', coalesce(c.name, 'Null')";
1458 $fields_part .= ', c.name as client';
1461 $what_to_concat .= ", ' - ', coalesce(p.name, 'Null')";
1462 $fields_part .= ', p.name as project';
1466 $what_to_concat .= ", ' - ', 'Null'";
1467 $fields_part .= ', null as task';
1471 $what_to_concat .= ", ' - ', 'Null'";
1472 $fields_part .= ', null as cf_1';
1475 switch ($group_by2) {
1477 $what_to_concat .= ", ' - ', ei.date";
1480 $what_to_concat .= ", ' - ', u.name";
1481 $fields_part .= ', u.name as user';
1484 $what_to_concat .= ", ' - ', coalesce(c.name, 'Null')";
1485 $fields_part .= ', c.name as client';
1488 $what_to_concat .= ", ' - ', coalesce(p.name, 'Null')";
1489 $fields_part .= ', p.name as project';
1493 $what_to_concat .= ", ' - ', 'Null'";
1494 $fields_part .= ', null as task';
1498 $what_to_concat .= ", ' - ', 'Null'";
1499 $fields_part .= ', null as cf_1';
1502 switch ($group_by3) {
1504 $what_to_concat .= ", ' - ', ei.date";
1507 $what_to_concat .= ", ' - ', u.name";
1508 $fields_part .= ', u.name as user';
1511 $what_to_concat .= ", ' - ', coalesce(c.name, 'Null')";
1512 $fields_part .= ', c.name as client';
1515 $what_to_concat .= ", ' - ', coalesce(p.name, 'Null')";
1516 $fields_part .= ', p.name as project';
1520 $what_to_concat .= ", ' - ', 'Null'";
1521 $fields_part .= ', null as task';
1525 $what_to_concat .= ", ' - ', 'Null'";
1526 $fields_part .= ', null as cf_1';
1529 // Remove garbage from the beginning.
1530 if ($what_to_concat)
1531 $what_to_concat = substr($what_to_concat, 8);
1532 $concat_part = "concat($what_to_concat) as group_field";
1533 return "$concat_part $fields_part";
1536 // makeCombinedSelectPart builds a list of fields for a combined select on a union for getSubtotals.
1537 // This is used when we include expenses.
1538 static function makeCombinedSelectPart($options) {
1539 $group_by1 = $options['group_by1'];
1540 $group_by2 = $options['group_by2'];
1541 $group_by3 = $options['group_by3'];
1543 $fields = "group_field";
1545 switch ($group_by1) {
1547 $fields .= ', user';
1550 $fields_part .= ', client';
1553 $fields .= ', project';
1557 $fields .= ', task';
1561 $fields .= ', cf_1';
1564 switch ($group_by2) {
1566 $fields .= ', user';
1569 $fields_part .= ', client';
1572 $fields .= ', project';
1576 $fields .= ', task';
1580 $fields .= ', cf_1';
1583 switch ($group_by3) {
1585 $fields .= ', user';
1588 $fields_part .= ', client';
1591 $fields .= ', project';
1595 $fields .= ', task';
1599 $fields .= ', cf_1';
1605 // makeJoinPart builds a left join part for getSubtotals query (for time items).
1606 static function makeJoinPart($options) {
1609 $trackingMode = $user->getTrackingMode();
1610 if (ttReportHelper::groupingBy('user', $options) || MODE_TIME == $trackingMode) {
1611 $join .= ' left join tt_users u on (l.user_id = u.id)';
1613 if (ttReportHelper::groupingBy('client', $options)) {
1614 $join .= ' left join tt_clients c on (l.client_id = c.id)';
1616 if (ttReportHelper::groupingBy('project', $options)) {
1617 $join .= ' left join tt_projects p on (l.project_id = p.id)';
1619 if (ttReportHelper::groupingBy('task', $options)) {
1620 $join .= ' left join tt_tasks t on (l.task_id = t.id)';
1622 if (ttReportHelper::groupingBy('cf_1', $options)) {
1623 $custom_fields = new CustomFields();
1624 if ($custom_fields->fields[0]['type'] == CustomFields::TYPE_TEXT)
1625 $join .= ' left join tt_custom_field_log cfl on (l.id = cfl.log_id and cfl.status = 1) left join tt_custom_field_options cfo on (cfl.value = cfo.id)';
1626 elseif ($custom_fields->fields[0]['type'] == CustomFields::TYPE_DROPDOWN)
1627 $join .= ' left join tt_custom_field_log cfl on (l.id = cfl.log_id and cfl.status = 1) left join tt_custom_field_options cfo on (cfl.option_id = cfo.id)';
1629 if ($options['show_cost'] && $trackingMode != MODE_TIME) {
1630 $join .= ' left join tt_user_project_binds upb on (l.user_id = upb.user_id and l.project_id = upb.project_id)';
1632 // Prepare inner joins.
1633 $inner_joins = null;
1634 if ($user->isPluginEnabled('ts') && $options['timesheet']) {
1635 $timesheet_option = $options['timesheet'];
1636 if ($timesheet_option == TIMESHEET_PENDING)
1637 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.submit_status = 1 and ts.approve_status is null)";
1638 else if ($timesheet_option == TIMESHEET_APPROVED)
1639 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.approve_status = 1)";
1640 else if ($timesheet_option == TIMESHEET_NOT_APPROVED)
1641 $inner_joins .= " inner join tt_timesheets ts on (l.timesheet_id = ts.id and ts.approve_status = 0)";
1643 $join .= $inner_joins;
1647 // makeWorkUnitPart builds an sql part for work units for time items.
1648 static function makeWorkUnitPart($options) {
1651 $workUnits = $options['show_work_units'];
1653 $unitTotalsOnly = $user->getConfigOption('unit_totals_only');
1654 $firstUnitThreshold = $user->getConfigInt('1st_unit_threshold', 0);
1655 $minutesInUnit = $user->getConfigInt('minutes_in_unit', 15);
1656 if ($unitTotalsOnly)
1657 $work_unit_part = ", if (sum(l.billable * time_to_sec(l.duration)/60) < $firstUnitThreshold, 0, ceil(sum(l.billable * time_to_sec(l.duration)/60/$minutesInUnit))) as units";
1659 $work_unit_part = ", sum(if(l.billable = 0 or time_to_sec(l.duration)/60 < $firstUnitThreshold, 0, ceil(time_to_sec(l.duration)/60/$minutesInUnit))) as units";
1661 return $work_unit_part;
1664 // makeCostPart builds a cost part for time items.
1665 static function makeCostPart($options) {
1668 if ($options['show_cost']) {
1669 if (MODE_TIME == $user->getTrackingMode())
1670 $cost_part = ", sum(cast(l.billable * coalesce(u.rate, 0) * time_to_sec(l.duration)/3600 as decimal(10, 2))) as cost";
1672 $cost_part .= ", sum(cast(l.billable * coalesce(upb.rate, 0) * time_to_sec(l.duration)/3600 as decimal(10,2))) as cost";
1677 // makeJoinExpensesPart builds a left join part for getSubtotals query for expense items.
1678 static function makeJoinExpensesPart($options) {
1681 if (ttReportHelper::groupingBy('user', $options)) {
1682 $join .= ' left join tt_users u on (ei.user_id = u.id)';
1684 if (ttReportHelper::groupingBy('client', $options)) {
1685 $join .= ' left join tt_clients c on (ei.client_id = c.id)';
1687 if (ttReportHelper::groupingBy('project', $options)) {
1688 $join .= ' left join tt_projects p on (ei.project_id = p.id)';
1693 // grouping determines if we are grouping the report by either group_by1,
1694 // group_by2, or group_by3 values passed in $options.
1695 static function grouping($options) {
1696 $grouping = ($options['group_by1'] != null && $options['group_by1'] != 'no_grouping') ||
1697 ($options['group_by2'] != null && $options['group_by2'] != 'no_grouping') ||
1698 ($options['group_by3'] != null && $options['group_by3'] != 'no_grouping');
1702 // groupingBy determines if we are grouping a report by a value of $what
1703 // ('date', 'user', 'project', etc.) by checking group_by1, group_by2,
1704 // and group_by3 values passed in $options.
1705 static function groupingBy($what, $options) {
1706 $grouping = ($options['group_by1'] == $what) || ($options['group_by2'] == $what) || ($options['group_by3'] == $what);
1710 // makeGroupByHeader builds a column header for a totals-only report using group_by1,
1711 // group_by2, and group_by3 values passed in $options.
1712 static function makeGroupByHeader($options) {
1714 global $custom_fields;
1716 $no_grouping = ($options['group_by1'] == null || $options['group_by1'] == 'no_grouping') &&
1717 ($options['group_by2'] == null || $options['group_by2'] == 'no_grouping') &&
1718 ($options['group_by3'] == null || $options['group_by3'] == 'no_grouping');
1719 if ($no_grouping) return null;
1721 if ($options['group_by1'] != null && $options['group_by1'] != 'no_grouping') {
1722 // We have group_by1.
1723 $group_by1 = $options['group_by1'];
1724 if ('cf_1' == $group_by1)
1725 $group_by_header .= ' - '.$custom_fields->fields[0]['label'];
1727 $key = 'label.'.$group_by1;
1728 $group_by_header .= ' - '.$i18n->get($key);
1731 if ($options['group_by2'] != null && $options['group_by2'] != 'no_grouping') {
1732 // We have group_by2.
1733 $group_by2 = $options['group_by2'];
1734 if ('cf_1' == $group_by2)
1735 $group_by_header .= ' - '.$custom_fields->fields[0]['label'];
1737 $key = 'label.'.$group_by2;
1738 $group_by_header .= ' - '.$i18n->get($key);
1741 if ($options['group_by3'] != null && $options['group_by3'] != 'no_grouping') {
1742 // We have group_by3.
1743 $group_by3 = $options['group_by3'];
1744 if ('cf_1' == $group_by3)
1745 $group_by_header .= ' - '.$custom_fields->fields[0]['label'];
1747 $key = 'label.'.$group_by3;
1748 $group_by_header .= ' - '.$i18n->get($key);
1751 $group_by_header = ltrim($group_by_header, ' -');
1752 return $group_by_header;
1755 // makeGroupByXmlTag creates an xml tag for a totals only report using group_by1,
1756 // group_by2, and group_by3 values passed in $options.
1757 static function makeGroupByXmlTag($options) {
1758 if ($options['group_by1'] != null && $options['group_by1'] != 'no_grouping') {
1759 // We have group_by1.
1760 $tag .= '_'.$options['group_by1'];
1762 if ($options['group_by2'] != null && $options['group_by2'] != 'no_grouping') {
1763 // We have group_by2.
1764 $tag .= '_'.$options['group_by2'];
1766 if ($options['group_by3'] != null && $options['group_by3'] != 'no_grouping') {
1767 // We have group_by3.
1768 $tag .= '_'.$options['group_by3'];
1770 $tag = ltrim($tag, '_');
1774 // makeGroupByLabel builds a label for one row in a "Totals only" report of grouped by items.
1775 // It does one thing: if we are grouping by date, the date format is converted for user.
1776 static function makeGroupByLabel($key, $options) {
1777 if (!ttReportHelper::groupingBy('date', $options))
1778 return $key; // No need to format.
1781 if ($user->getDateFormat() == DB_DATEFORMAT)
1782 return $key; // No need to format.
1785 if (preg_match('/\d\d\d\d-\d\d-\d\d/', $key, $matches)) {
1786 // Replace the first found match of a date in DB_DATEFORMAT.
1787 // This is not entirely clean but better than nothing for a label in a row.
1788 $userDate = ttDateToUserFormat($matches[0]);
1789 $label = str_replace($matches[0], $userDate, $key);