diff --git a/SumasenLibs/excel_lib/sumaexcel/sumaexcel.py b/SumasenLibs/excel_lib/sumaexcel/sumaexcel.py index f019ef7..9ac7c9d 100644 --- a/SumasenLibs/excel_lib/sumaexcel/sumaexcel.py +++ b/SumasenLibs/excel_lib/sumaexcel/sumaexcel.py @@ -418,17 +418,38 @@ class SumasenExcel: self.current_sheet = self.workbook.create_sheet('Sheet') else: self.current_sheet = self.workbook['Sheet'] - - # セルの内容とスタイルをコピー - for row in range(min_row, max_row + 1): - for col in range(min_col, max_col + 1): + + # Copy column widths + for col in range(orig_min_col, orig_max_col + 1): + col_letter = get_column_letter(col) + if col_letter in self.template_sheet.column_dimensions: + self.current_sheet.column_dimensions[col_letter].width = \ + self.template_sheet.column_dimensions[col_letter].width + + # Copy merged cells + for merged_range in self.template_sheet.merged_cells: + min_col, min_row, max_col, max_row = range_boundaries(str(merged_range)) + # Check if merge range intersects with our copy range + if (min_col >= orig_min_col and max_col <= orig_max_col and + min_row >= orig_min_row and max_row <= orig_max_row): + # Calculate target merge range + target_merge_min_row = target_min_row + (min_row - orig_min_row) + target_merge_max_row = target_min_row + (max_row - orig_min_row) + target_merge_range = f"{get_column_letter(min_col)}{target_merge_min_row}:" \ + f"{get_column_letter(max_col)}{target_merge_max_row}" + self.current_sheet.merge_cells(target_merge_range) + + # Copy cell contents and styles + row_offset = target_min_row - orig_min_row + for row in range(orig_min_row, orig_max_row + 1): + for col in range(orig_min_col, orig_max_col + 1): source_cell = self.template_sheet.cell(row=row, column=col) - target_cell = self.current_sheet.cell(row=row, column=col) - - # 値のコピー + target_cell = self.current_sheet.cell(row=row+row_offset, column=col) + + # Copy value target_cell.value = source_cell.value - - # スタイルのコピー + + # Copy styles if source_cell.has_style: target_cell.font = copy(source_cell.font) target_cell.border = copy(source_cell.border) @@ -436,6 +457,38 @@ class SumasenExcel: target_cell.number_format = source_cell.number_format target_cell.protection = copy(source_cell.protection) target_cell.alignment = copy(source_cell.alignment) + + # Copy page setup + target_page_setup = self.current_sheet.page_setup + source_page_setup = self.template_sheet.page_setup + + # Copy all page setup attributes + target_page_setup.paperSize = source_page_setup.paperSize + target_page_setup.orientation = source_page_setup.orientation + target_page_setup.fitToHeight = source_page_setup.fitToHeight + target_page_setup.fitToWidth = source_page_setup.fitToWidth + target_page_setup.zoom = source_page_setup.zoom + target_page_setup.scale = source_page_setup.scale + + # Copy margins + target_margins = self.current_sheet.page_margins + source_margins = self.template_sheet.page_margins + + target_margins.left = source_margins.left + target_margins.right = source_margins.right + target_margins.top = source_margins.top + target_margins.bottom = source_margins.bottom + target_margins.header = source_margins.header + target_margins.footer = source_margins.footer + + # Copy print options + target_print = self.current_sheet.print_options + source_print = self.template_sheet.print_options + + target_print.horizontalCentered = source_print.horizontalCentered + target_print.verticalCentered = source_print.verticalCentered + target_print.gridLines = source_print.gridLines + target_print.gridLinesSet = source_print.gridLinesSet return {"status": True, "message": "Successfully copied template range"} diff --git a/SumasenLibs/excel_lib/testdata/~$certificate_template.xlsx b/SumasenLibs/excel_lib/testdata/~$certificate_template.xlsx new file mode 100644 index 0000000..52abcff Binary files /dev/null and b/SumasenLibs/excel_lib/testdata/~$certificate_template.xlsx differ diff --git a/rog/postgres_views.sql b/rog/postgres_views.sql new file mode 100644 index 0000000..40c3075 --- /dev/null +++ b/rog/postgres_views.sql @@ -0,0 +1,144 @@ +-- まず既存のビューをすべて削除 +DROP MATERIALIZED VIEW IF EXISTS mv_entry_details CASCADE; +DROP VIEW IF EXISTS v_category_rankings CASCADE; +DROP VIEW IF EXISTS v_checkin_summary CASCADE; + +-- チェックポイントの集計用ビュー +CREATE VIEW v_checkin_summary AS +SELECT + event_code, + zekken_number, -- 文字列として保持 + COUNT(*) as total_checkins, + COUNT(CASE WHEN buy_flag THEN 1 END) as purchase_count, + SUM(points) as total_points, + SUM(CASE WHEN buy_flag THEN points ELSE 0 END) as bonus_points, + SUM(CASE WHEN NOT buy_flag THEN points ELSE 0 END) as normal_points, + SUM(COALESCE(late_point, 0)) as penalty_points, + MAX(create_at) as last_checkin +FROM + gps_checkins +GROUP BY + event_code, zekken_number; + +-- カテゴリー内ランキング計算用ビュー +CREATE VIEW v_category_rankings AS +SELECT + e.id, + e.event_id, + ev.event_name, + e.category_id, + CAST(e.zekken_number AS TEXT) as zekken_number, -- 数値を文字列に変換 + COALESCE(cs.total_points, 0) as total_score, + RANK() OVER (PARTITION BY e.event_id, e.category_id + ORDER BY COALESCE(cs.total_points, 0) DESC) as ranking, + COUNT(*) OVER (PARTITION BY e.event_id, e.category_id) as total_participants +FROM + rog_entry e + JOIN rog_newevent2 ev ON e.event_id = ev.id + LEFT JOIN v_checkin_summary cs ON ev.event_name = cs.event_code + AND CAST(e.zekken_number AS TEXT) = cs.zekken_number +WHERE + e.is_active = true; + +-- マテリアライズドビューの作成 +-- マテリアライズドビューの再作成 +DROP MATERIALIZED VIEW IF EXISTS mv_entry_details; + +CREATE MATERIALIZED VIEW mv_entry_details AS +SELECT + -- エントリー基本情報 + e.id, + CAST(e.zekken_number AS TEXT) as zekken_number, + e.is_active, + e."hasParticipated", + e."hasGoaled", + e.date as entry_date, + + -- イベント情報 + ev.event_name, + ev.start_datetime, + ev.end_datetime, + ev."deadlineDateTime", + + -- カテゴリー情報 + nc.category_name, + nc.category_number, + nc.duration, + nc.num_of_member, + nc.family as is_family_category, + nc.female as is_female_category, + + -- チーム情報 + t.team_name, + + -- オーナー情報 + cu.email as owner_email, + cu.firstname as owner_firstname, + cu.lastname as owner_lastname, + cu.date_of_birth as owner_birth_date, + cu.female as owner_is_female, + + -- スコア情報 + COALESCE(cs.total_points, 0) as total_points, + COALESCE(cs.normal_points, 0) as normal_points, + COALESCE(cs.bonus_points, 0) as bonus_points, + COALESCE(cs.penalty_points, 0) as penalty_points, + COALESCE(cs.total_checkins, 0) as checkin_count, + COALESCE(cs.purchase_count, 0) as purchase_count, + + -- ランキング情報 + cr.ranking as category_rank, + cr.total_participants, + + -- チームメンバー情報(JSON形式で格納) + jsonb_agg( + jsonb_build_object( + 'email', m.user_id, + 'firstname', m.firstname, + 'lastname', m.lastname, + 'birth_date', m.date_of_birth, + 'is_female', m.female, + 'is_temporary', m.is_temporary, + 'status', CASE + WHEN m.is_temporary THEN 'TEMPORARY' + WHEN m.date_of_birth IS NULL THEN 'PENDING' + ELSE 'ACTIVE' + END, + 'member_type', CASE + WHEN m.user_id = e.owner_id THEN 'OWNER' + ELSE 'MEMBER' + END + ) ORDER BY + CASE WHEN m.user_id = e.owner_id THEN 0 ELSE 1 END, -- オーナーを最初に + m.id + ) FILTER (WHERE m.id IS NOT NULL) as team_members + +FROM + rog_entry e + INNER JOIN rog_newevent2 ev ON e.event_id = ev.id + INNER JOIN rog_newcategory nc ON e.category_id = nc.id + INNER JOIN rog_team t ON e.team_id = t.id + LEFT JOIN rog_customuser cu ON e.owner_id = cu.id + LEFT JOIN v_checkin_summary cs ON ev.event_name = cs.event_code + AND CAST(e.zekken_number AS TEXT) = cs.zekken_number + LEFT JOIN v_category_rankings cr ON e.id = cr.id + LEFT JOIN rog_member m ON t.id = m.team_id + +GROUP BY + e.id, e.zekken_number, e.is_active, e."hasParticipated", e."hasGoaled", e.date, + ev.event_name, ev.start_datetime, ev.end_datetime, ev."deadlineDateTime", + nc.category_name, nc.category_number, nc.duration, nc.num_of_member, + nc.family, nc.female, + t.team_name, + cu.email, cu.firstname, cu.lastname, cu.date_of_birth, cu.female, + cs.total_points, cs.normal_points, cs.bonus_points, cs.penalty_points, + cs.total_checkins, cs.purchase_count, cs.last_checkin, + cr.ranking, cr.total_participants, + e.owner_id; -- オーナーIDをGROUP BYに追加 + +-- インデックスの再作成 +CREATE UNIQUE INDEX idx_mv_entry_details_event_zekken +ON mv_entry_details(event_name, zekken_number); + +-- ビューの更新 +REFRESH MATERIALIZED VIEW mv_entry_details; \ No newline at end of file