query('RESET QUERY CACHE;'); $db->query('FLUSH QUERY CACHE'); // Initialize variables with defaults $account_type = ''; $saldo_type = ''; $data = array(); $sum = array(); $idToPdf = ''; if (!empty($_REQUEST['submit'])) { // Sanitize and validate inputs $account_type = isset($_REQUEST['account_type']) ? trim($_REQUEST['account_type']) : ''; if ($account_type == 'a') { $account_type = ''; } $saldo_type = isset($_REQUEST['saldo_type']) ? trim($_REQUEST['saldo_type']) : ''; $type2 = isset($_REQUEST['type2']) ? $db->quote(trim($_REQUEST['type2'])) : ''; $user_id = isset($_REQUEST['user_id']) ? $db->quote(trim($_REQUEST['user_id'])) : ''; // Build WHERE conditions safely $conditions = array("t.deleted='0'"); if ($saldo_type != '') { $conditions[] = "t.settled!='1'"; } if (!empty($type2)) { $conditions[] = "a.account_type2='" . $type2 . "'"; } if (!empty($user_id)) { $conditions[] = "a.assigned_user_id='" . $user_id . "'"; } // Build account type condition $account_condition = ''; if ($account_type != '') { $account_condition = " AND (a.account_type='rs' OR a.account_type = '" . $db->quote($account_type) . "')"; } // Optimized query - get all needed data in one go $query = "SELECT DISTINCT t.parent_id, a.index_dbf, a.name as account_name, a.currency_id, a.id as account_id FROM ecmtransactions as t INNER JOIN accounts AS a ON t.parent_id = a.id WHERE " . implode(' AND ', $conditions) . $account_condition . " ORDER BY a.index_dbf"; $clients = $db->query($query); $client_ids = array(); $clients_data = array(); // First pass - collect all client IDs and data while ($c = $db->fetchByAssoc($clients)) { if (!empty($c['parent_id'])) { $client_ids[] = $c['parent_id']; $clients_data[] = $c; } } // Get all financial data in one batch $financial_batch = getAllFinancialData($client_ids); // Cache currency objects to avoid repeated database calls $currency_cache = array(); foreach ($clients_data as $c) { $parent_id = $c['parent_id']; // Skip if no financial data if (!isset($financial_batch[$parent_id])) { continue; } $row = array(); $row['id'] = $parent_id; $row['name'] = $c['account_name']; $row['index'] = $c['index_dbf']; // Use cached currency data $currency_id = !empty($c['currency_id']) ? $c['currency_id'] : 'PLN'; if (!isset($currency_cache[$currency_id])) { $currency_obj = new Currency(); $currency_obj->retrieve($currency_id); $currency_cache[$currency_id] = $currency_obj->name; } $row['currency_id'] = $currency_cache[$currency_id]; // Use pre-calculated financial data $fin_data = $financial_batch[$parent_id]; $row['unsettled'] = $fin_data['unsettled']; $row['not_overdue'] = $fin_data['not_overdue']; $row['overdue'] = $fin_data['overdue']; $row['2'] = $fin_data['2']; $row['3'] = $fin_data['3']; $row['4'] = $fin_data['4']; $row['5'] = $fin_data['5']; $row['6'] = $fin_data['6']; $row['saldo'] = $fin_data['saldo']; $row['today_saldo'] = 0; // Apply saldo filters if ($saldo_type == 'plus' && $row['saldo'] <= 0) continue; if ($saldo_type == 'minus' && $row['saldo'] >= 0) continue; if ($saldo_type == 'zero' && $row['saldo'] != 0) continue; if ($saldo_type == '' && $row['saldo'] == 0) continue; $idToPdf .= $row['id'] . ','; // Accumulate sums by currency if (!isset($sum[$currency_id])) { $sum[$currency_id] = array( 'unsettled' => 0, 'not_overdue' => 0, 'overdue' => 0, '2' => 0, '3' => 0, '4' => 0, '5' => 0, '6' => 0, 'saldo' => 0, 'today_saldo' => 0, 'currency_id' => $currency_cache[$currency_id] ); } $sum[$currency_id]['unsettled'] += $row['unsettled']; $sum[$currency_id]['not_overdue'] += $row['not_overdue']; $sum[$currency_id]['overdue'] += $row['overdue']; $sum[$currency_id]['2'] += $row['2']; $sum[$currency_id]['3'] += $row['3']; $sum[$currency_id]['4'] += $row['4']; $sum[$currency_id]['5'] += $row['5']; $sum[$currency_id]['6'] += $row['6']; $sum[$currency_id]['saldo'] += $row['saldo']; $sum[$currency_id]['today_saldo'] += $row['today_saldo']; $data[] = $row; } } // Get user list with single optimized query $user_list = array(); $users_query = "SELECT id, CONCAT(COALESCE(first_name, ''), ' ', COALESCE(last_name, '')) as full_name FROM users WHERE deleted=0 ORDER BY first_name, last_name"; $users_result = $db->query($users_query); while ($user_data = $db->fetchByAssoc($users_result)) { $user_list[$user_data['id']] = trim($user_data['full_name']); } // Initialize Smarty template $ss = new Sugar_Smarty(); global $mod_strings, $app_list_strings; $ss->assign("MOD", $mod_strings); $ss->assign("DATA", $data); $ss->assign("SUM", $sum); $ss->assign("SORT", array()); $ss->assign("account_type", $account_type); $app_list_strings['account_type_dom']['a'] = 'Wszystkie'; $ss->assign("account_type_list", $app_list_strings['account_type_dom']); $ss->assign("saldo_type", $saldo_type); $ss->assign("saldo_date_val", isset($_REQUEST['saldo_date_val']) ? $_REQUEST['saldo_date_val'] : ''); $ss->assign("idToPdf", rtrim($idToPdf, ',')); $ss->assign("type", isset($_REQUEST['type2']) ? $_REQUEST['type2'] : ''); $ss->assign("type2", $app_list_strings['account_type2_dom']); $ss->assign("user_id", isset($_REQUEST['user_id']) ? $_REQUEST['user_id'] : ''); $ss->assign("users", $user_list); echo $ss->display('modules/EcmPaymentStates/tpls/summary1.tpl'); // OPTIMIZED CORE FUNCTION - Gets all financial data in one query function getAllFinancialData($client_ids) { static $global_cache = null; if ($global_cache !== null && !empty($global_cache)) { return $global_cache; } if (empty($client_ids)) { return array(); } $db = $GLOBALS['db']; $today = date('Y-m-d'); $ids_string = "'" . implode("','", array_unique($client_ids)) . "'"; // Single comprehensive query for all financial calculations $comprehensive_query = " SELECT t.parent_id, t.type, t.settled, t.value, t.payment_date, COALESCE(settled_data.settled_amount, 0) as settled_amount FROM ecmtransactions t LEFT JOIN ( SELECT parent_trans.id as transaction_id, SUM( CASE WHEN parent_trans.type = '0' AND rel_trans.type = '0' AND parent_trans.value < 0 AND r.value < 0 THEN ABS(r.value) WHEN parent_trans.type = '0' THEN r.value ELSE ABS(r.value) END ) as settled_amount FROM ecmtransactions parent_trans LEFT JOIN ecmtransactions_rel r ON (r.ecmtransaction_a_id = parent_trans.id OR r.ecmtransaction_b_id = parent_trans.id) LEFT JOIN ecmtransactions rel_trans ON ( rel_trans.id = CASE WHEN r.ecmtransaction_a_id = parent_trans.id THEN r.ecmtransaction_b_id ELSE r.ecmtransaction_a_id END AND rel_trans.deleted = '0' ) WHERE parent_trans.parent_id IN ($ids_string) AND parent_trans.deleted = '0' GROUP BY parent_trans.id ) settled_data ON settled_data.transaction_id = t.id WHERE t.parent_id IN ($ids_string) AND t.deleted = '0' ORDER BY t.parent_id, t.payment_date "; $result = $db->query($comprehensive_query); $financial_data = array(); while ($row = $db->fetchByAssoc($result)) { $parent_id = $row['parent_id']; $type = $row['type']; $settled = $row['settled']; $value = floatval($row['value']); $settled_amount = floatval($row['settled_amount']); $payment_date = $row['payment_date']; if (!isset($financial_data[$parent_id])) { $financial_data[$parent_id] = array( 'unsettled' => 0, 'not_overdue' => 0, 'overdue' => 0, '2' => 0, '3' => 0, '4' => 0, '5' => 0, '6' => 0, 'saldo' => 0 ); } // Calculate effective value based on settlement $effective_value = ($settled == '1') ? $value : ($value - $settled_amount); // Determine date category $days_diff = (strtotime($today) - strtotime($payment_date)) / (60 * 60 * 24); // Apply business logic based on type and date if ($type == '1') { // MA (receivable) $financial_data[$parent_id]['saldo'] += $effective_value; if ($days_diff < 0) { // Future date $financial_data[$parent_id]['not_overdue'] += $effective_value; } if ($settled != '1') { $financial_data[$parent_id]['unsettled'] += $effective_value; } } else { // WINIEN (payable) $financial_data[$parent_id]['saldo'] -= $effective_value; if ($days_diff >= 0 && $settled != '1') { // Past due and not settled $financial_data[$parent_id]['overdue'] += $effective_value; } if ($settled != '1') { $financial_data[$parent_id]['unsettled'] += $effective_value; } } // Categorize by aging periods (only for non-settled) if ($settled != '1') { if ($days_diff >= 1 && $days_diff <= 30) { $financial_data[$parent_id]['2'] += $effective_value; } elseif ($days_diff >= 31 && $days_diff <= 60) { $financial_data[$parent_id]['3'] += $effective_value; } elseif ($days_diff >= 61 && $days_diff <= 90) { $financial_data[$parent_id]['4'] += $effective_value; } elseif ($days_diff >= 91 && $days_diff <= 180) { $financial_data[$parent_id]['5'] += $effective_value; } elseif ($days_diff > 180) { $financial_data[$parent_id]['6'] += $effective_value; } } } $global_cache = $financial_data; return $financial_data; } // Legacy function wrappers for backward compatibility (now use cached data) function getData($id, $expired) { static $batch_data = null; if ($batch_data === null) { $batch_data = getAllFinancialData(array($id)); } if (!isset($batch_data[$id])) { return 0; } $data = $batch_data[$id]; switch ($expired) { case 0: return $data['unsettled']; // All unsettled case 1: return $data['overdue']; // Overdue case 7: return $data['not_overdue']; // Not overdue case 8: case 9: return $data['saldo']; // Saldo default: return getData2($id, $expired); } } function getData2($id, $expired, $dates = null) { static $batch_data = null; if ($batch_data === null) { $batch_data = getAllFinancialData(array($id)); } if (!isset($batch_data[$id])) { return 0; } $data = $batch_data[$id]; switch ($expired) { case 2: return $data['2']; // 1-30 days case 3: return $data['3']; // 31-60 days case 4: return $data['4']; // 61-90 days case 5: return $data['5']; // 91-180 days case 6: return $data['6']; // 180+ days case 9: return $data['saldo']; // Saldo with date default: return 0; } } // Comparison functions (PHP 5.6 compatible) function cmpUnsettled($a, $b) { if ($a['unsettled'] == $b['unsettled']) return 0; return ($a['unsettled'] < $b['unsettled']) ? -1 : 1; } function cmpUnsettledDesc($a, $b) { if ($a['unsettled'] == $b['unsettled']) return 0; return ($a['unsettled'] < $b['unsettled']) ? 1 : -1; } function cmpNotOverdue($a, $b) { if ($a['not_overdue'] == $b['not_overdue']) return 0; return ($a['not_overdue'] < $b['not_overdue']) ? -1 : 1; } function cmpNotOverdueDesc($a, $b) { if ($a['not_overdue'] == $b['not_overdue']) return 0; return ($a['not_overdue'] < $b['not_overdue']) ? 1 : -1; } function cmpOverdue($a, $b) { if ($a['overdue'] == $b['overdue']) return 0; return ($a['overdue'] < $b['overdue']) ? -1 : 1; } function cmpOverdueDesc($a, $b) { if ($a['overdue'] == $b['overdue']) return 0; return ($a['overdue'] < $b['overdue']) ? 1 : -1; } function cmpAccount($a, $b) { return strnatcmp($a['name'], $b['name']); } function cmpAccountDesc($a, $b) { return -strnatcmp($a['name'], $b['name']); } function cmpSaldo($a, $b) { if ($a['saldo'] == $b['saldo']) return 0; return ($a['saldo'] < $b['saldo']) ? -1 : 1; } function cmpSaldoDesc($a, $b) { if ($a['saldo'] == $b['saldo']) return 0; return ($a['saldo'] < $b['saldo']) ? 1 : -1; } function cmpTodaySaldo($a, $b) { if ($a['today_saldo'] == $b['today_saldo']) return 0; return ($a['today_saldo'] < $b['today_saldo']) ? -1 : 1; } function cmpTodaySaldoDesc($a, $b) { if ($a['today_saldo'] == $b['today_saldo']) return 0; return ($a['today_saldo'] < $b['today_saldo']) ? 1 : -1; } // Helper function for date conditions (now unused but kept for compatibility) function getDateConditions($expired, $dates = null) { $today = date('Y-m-d'); switch ($expired) { case 1: return "AND t.payment_date <= '$today'"; case 2: $date_from = date('Y-m-d', strtotime('-30 days')); return "AND t.payment_date >= '$date_from' AND t.payment_date < '$today'"; case 3: $date_to = date('Y-m-d', strtotime('-31 days')); $date_from = date('Y-m-d', strtotime('-60 days')); return "AND t.payment_date >= '$date_from' AND t.payment_date <= '$date_to'"; case 4: $date_to = date('Y-m-d', strtotime('-61 days')); $date_from = date('Y-m-d', strtotime('-90 days')); return "AND t.payment_date >= '$date_from' AND t.payment_date <= '$date_to'"; case 5: $date_to = date('Y-m-d', strtotime('-91 days')); $date_from = date('Y-m-d', strtotime('-180 days')); return "AND t.payment_date >= '$date_from' AND t.payment_date <= '$date_to'"; case 6: $date = date('Y-m-d', strtotime('-181 days')); return "AND t.payment_date <= '$date'"; case 9: $target_date = $dates ? date('Y-m-d', strtotime($dates)) : $today; return "AND t.payment_date <= '$target_date'"; default: return "AND 1=1"; } }