ConfRates::getLanesActive(), // 'provs' => Region::listProv(), // 'vendors' => Users::getUsersActiveByRole(Users::ROLE_VENDOR), // 'truck_types' => ConfTruckTypes::listTruckTypes(ConfTruckTypes::IS_ACTIVE), ]; return view('menu_v1.reports.vehicle_trips', $data); } public function api_report_vehicle_trips_list(Request $req) { // Validate input // date in unix datetime format // dd($req->type); $rules = [ // 'from_date' => 'required|date', // 'to_date' => 'required|date|after_or_equal:from_date', 'type' => 'nullable|in:report,list', // enum "report", "list". nullable default "list" ]; $isValidInput = Validator::make($req->all(), $rules); if (!$isValidInput->passes()) { $apiResp = Responses::bad_input($isValidInput->messages()->first()); return new Response($apiResp, $apiResp["meta"]["code"]); } $from_date = $req->input('from_date'); $to_date = $req->input('to_date'); // $from_date = 1756054800; // $to_date = 1756745940; try { $q = " WITH trips AS ( SELECT t.*, -- mark the start of a trip when ignition=4 and previous ignition <> 4 CASE WHEN ignition = 4 AND LAG(ignition, 1, 0) OVER (PARTITION BY vhc_id ORDER BY crt_d) <> 4 THEN 1 ELSE 0 END AS trip_start FROM t_gps_tracks t WHERE t.latitude IS NOT NULL AND t.longitude IS NOT NULL AND t.action = 'location' AND t.crt_d BETWEEN ? AND ? ) , numbered AS ( SELECT *, -- assign a trip_id by cumulative sum of trip_start SUM(trip_start) OVER (PARTITION BY vhc_id ORDER BY crt_d) AS trip_id FROM trips ) SELECT v.id, coalesce(max(a.trip_id), 0) numOfTrip, SUM(pre_milleage) AS total_milleage, v.name, v.nopol1 FROM t_vehicles v left join numbered a on a.vhc_id = v.id WHERE v.dlt is null GROUP BY v.id ORDER BY v.id; "; $d = [$from_date, $to_date]; $list = DB::select($q, $d); // RETURN 1 - LIST if($req->type != 'report'){ $apiResp = Responses::success("success list vehicles report"); $apiResp["data"] = $list; return new Response($apiResp, $apiResp["meta"]["code"]); } // RETURN 2 - REPORT if($req->type == 'report'){ $headings = ['Name', 'License Plate', 'Number of Trip', 'Total Mileage']; $export = new class($list, $headings) implements FromArray, WithHeadings { private $list; private $headings; public function __construct($list, $headings) { $this->list = $list; $this->headings = $headings; } public function array(): array { return array_map(function ($item) { return [ $item->name, $item->nopol1, $item->numOfTrip, $item->total_milleage, ]; }, $this->list); } public function headings(): array { return $this->headings; } // Start table from A3 public function startCell(): string { return 'A3'; } // Add title & border styling public function styles(Worksheet $sheet) { $tgl0 = date('d-m-Y', $GLOBALS['from_date']); $tgl1 = date('d-m-Y', $GLOBALS['to_date']); // Title in A1 $sheet->setCellValue('A1', 'Vehicle Trip Report $tgl0 until $tgl1'); $sheet->mergeCells('A1:D1'); // Merge across 4 columns $sheet->getStyle('A1')->getFont()->setBold(true)->setSize(16); $sheet->getStyle('A1')->getAlignment()->setHorizontal('center'); // Get last row $lastRow = $this->list->count() + 3; // 3 = heading row $range = "A3:D{$lastRow}"; // Add borders $sheet->getStyle($range)->getBorders()->getAllBorders() ->setBorderStyle(\PhpOffice\PhpSpreadsheet\Style\Border::BORDER_THIN); // Bold headings $sheet->getStyle('A3:D3')->getFont()->setBold(true); return []; } }; return Excel::download($export, 'trip_report.xlsx'); } } catch (\Exception $e) { $apiResp = Responses::error($e->getMessage()); return new Response($apiResp, $apiResp["meta"]["code"]); // return Responses::json(Responses::SERVER_ERROR, 'An error occurred while generating the report.', (object)[]); } } }