drop view if exists vw_activity_registration_base; drop view if exists vw_activity_payment_detail; drop view if exists vw_activity_follower_statistics; drop view if exists vw_activity_item_statistics; drop view if exists vw_activity_payment_status; drop view if exists vw_activity_registration_trend; drop view if exists vw_activity_payment_trend; drop view if exists vw_activity_unpaid_detail; drop view if exists vw_activity_transfer_reconciliation; GO -- 1. 法會報名基礎資料 VIEW CREATE VIEW vw_activity_registration_base AS SELECT a.num AS 活動編號, a.subject AS 活動名稱, a.startDate_solar AS 活動開始日期, a.endDate_solar AS 活動結束日期, po.order_no AS 報名單號, po.up_time AS 報名日期, po.keyin1 AS 報名狀態, f.num AS 信眾編號, f.f_number AS 信眾代號, f.u_name AS 信眾姓名, f.phone AS 聯絡電話, f.identity_type AS 身分別, f.country AS 國籍, pod.num AS 報名明細編號, ai.num AS 品項編號, ai.subject AS 品項名稱, ai.category AS 品項分類, pod.price AS 單價, pod.qty AS 數量, pod.price * pod.qty AS 應繳金額, pod.pay AS 已收金額, (pod.price * pod.qty - ISNULL(pod.pay, 0)) AS 未收金額, pod.pay_date AS 付款期限, pod.start_date AS 開始日期, pod.due_date AS 到期日期, pod.keyin1 AS 明細狀態, pod.demo AS 備註 FROM activity a INNER JOIN pro_order po ON a.num = po.activity_num INNER JOIN followers f ON po.f_num = f.num INNER JOIN pro_order_detail pod ON po.order_no = pod.order_no INNER JOIN actItem ai ON pod.actItem_num = ai.num; GO -- 2. 收款明細基礎資料 VIEW CREATE VIEW vw_activity_payment_detail AS SELECT a.num AS 活動編號, a.subject AS 活動名稱, po.order_no AS 報名單號, f.u_name AS 信眾姓名, pod.num AS 報名明細編號, ai.subject AS 品項名稱, por.num AS 收款記錄編號, por.price AS 收款金額, por.payment AS 付款方式, por.pay_date AS 收款日期, por.organization AS 收款機構, por.bank_code AS 銀行代碼, por.transfer_id AS 匯款記錄ID, por.reconcile_memo AS 對帳備註, tr.name AS 匯款人姓名, tr.phone AS 匯款人電話, tr.amount AS 匯款金額, tr.check_date AS 入帳日期, tr.status AS 匯款狀態 FROM activity a INNER JOIN pro_order po ON a.num = po.activity_num INNER JOIN followers f ON po.f_num = f.num INNER JOIN pro_order_detail pod ON po.order_no = pod.order_no INNER JOIN actItem ai ON pod.actItem_num = ai.num LEFT JOIN pro_order_record por ON pod.num = por.detail_num LEFT JOIN transfer_register tr ON por.transfer_id = tr.id; GO -- 3. 信眾報名統計 VIEW CREATE VIEW vw_activity_follower_statistics AS SELECT 活動編號, 活動名稱, 信眾編號, 信眾代號, 信眾姓名, 聯絡電話, 身分別, 國籍, COUNT(DISTINCT 報名單號) AS 報名單數, COUNT(報名明細編號) AS 報名品項數, SUM(應繳金額) AS 應繳總金額, SUM(已收金額) AS 已收總金額, SUM(未收金額) AS 未收總金額, CASE WHEN SUM(未收金額) = 0 THEN '已繳清' WHEN SUM(未收金額) = SUM(應繳金額) THEN '未繳' ELSE '部分繳款' END AS 繳款狀態 FROM vw_activity_registration_base GROUP BY 活動編號, 活動名稱, 信眾編號, 信眾代號, 信眾姓名, 聯絡電話, 身分別, 國籍; GO -- 4. 品項報名統計 VIEW CREATE VIEW vw_activity_item_statistics AS SELECT 活動編號, 活動名稱, 品項編號, 品項名稱, 品項分類, 單價, COUNT(報名明細編號) AS 報名數量, SUM(數量) AS 總數量, SUM(應繳金額) AS 應繳總金額, SUM(已收金額) AS 已收總金額, SUM(未收金額) AS 未收總金額, CASE WHEN COUNT(報名明細編號) = 0 THEN 0 ELSE AVG(已收金額) END AS 平均已收金額, CASE WHEN SUM(未收金額) = 0 THEN '已收齊' WHEN SUM(未收金額) = SUM(應繳金額) THEN '未收款' ELSE '部分收款' END AS 收款狀態 FROM vw_activity_registration_base GROUP BY 活動編號, 活動名稱, 品項編號, 品項名稱, 品項分類, 單價; GO -- 5. 收款狀態統計 VIEW CREATE VIEW vw_activity_payment_status AS SELECT 活動編號, 活動名稱, '總計' AS 統計項目, COUNT(DISTINCT 報名單號) AS 報名單數, COUNT(報名明細編號) AS 報名品項數, SUM(應繳金額) AS 應繳總金額, SUM(已收金額) AS 已收總金額, SUM(未收金額) AS 未收總金額, CASE WHEN SUM(應繳金額) = 0 THEN 0 ELSE ROUND(SUM(已收金額) * 100.0 / SUM(應繳金額), 2) END AS 收款率 FROM vw_activity_registration_base GROUP BY 活動編號, 活動名稱 UNION ALL SELECT 活動編號, 活動名稱, CASE WHEN 未收金額 = 0 THEN '已繳清' WHEN 未收金額 = 應繳金額 THEN '未繳' ELSE '部分繳款' END AS 統計項目, COUNT(DISTINCT 報名單號) AS 報名單數, COUNT(報名明細編號) AS 報名品項數, SUM(應繳金額) AS 應繳總金額, SUM(已收金額) AS 已收總金額, SUM(未收金額) AS 未收總金額, CASE WHEN SUM(應繳金額) = 0 THEN 0 ELSE ROUND(SUM(已收金額) * 100.0 / SUM(應繳金額), 2) END AS 收款率 FROM vw_activity_registration_base GROUP BY 活動編號, 活動名稱, CASE WHEN 未收金額 = 0 THEN '已繳清' WHEN 未收金額 = 應繳金額 THEN '未繳' ELSE '部分繳款' END; GO -- 6. 報名趨勢分析 VIEW CREATE VIEW vw_activity_registration_trend AS SELECT 活動編號, 活動名稱, CAST(報名日期 AS DATE) AS 報名日期, COUNT(DISTINCT 報名單號) AS 當日報名單數, COUNT(報名明細編號) AS 當日報名品項數, SUM(應繳金額) AS 當日應繳金額, SUM(已收金額) AS 當日已收金額, SUM(未收金額) AS 當日未收金額 FROM vw_activity_registration_base GROUP BY 活動編號, 活動名稱, CAST(報名日期 AS DATE); GO -- 7. 收款趨勢分析 VIEW CREATE VIEW vw_activity_payment_trend AS SELECT 活動編號, 活動名稱, CAST(收款日期 AS DATE) AS 收款日期, COUNT(收款記錄編號) AS 當日收款筆數, SUM(收款金額) AS 當日收款金額, COUNT(DISTINCT 報名單號) AS 當日收款單數, CASE WHEN COUNT(收款記錄編號) = 0 THEN 0 ELSE AVG(收款金額) END AS 平均收款金額 FROM vw_activity_payment_detail WHERE 收款日期 IS NOT NULL GROUP BY 活動編號, 活動名稱, CAST(收款日期 AS DATE); GO -- 8. 未收款明細 VIEW CREATE VIEW vw_activity_unpaid_detail AS SELECT 活動編號, 活動名稱, 報名單號, 信眾姓名, 聯絡電話, 品項名稱, 應繳金額, 已收金額, 未收金額, 付款期限, CASE WHEN 付款期限 < GETDATE() THEN '已逾期' WHEN 付款期限 <= DATEADD(DAY, 3, GETDATE()) THEN '即將到期' ELSE '未到期' END AS 到期狀態 FROM vw_activity_registration_base WHERE 未收金額 > 0; GO -- 9. 匯款對帳明細 VIEW CREATE VIEW vw_activity_transfer_reconciliation AS SELECT 活動編號, 活動名稱, 匯款記錄ID, 匯款人姓名, 匯款人電話, 匯款金額, 入帳日期, 匯款狀態, COUNT(收款記錄編號) AS 關聯收款筆數, SUM(收款金額) AS 已對帳金額, CASE WHEN SUM(收款金額) IS NULL THEN 匯款金額 ELSE 匯款金額 - SUM(收款金額) END AS 剩餘金額 FROM vw_activity_payment_detail WHERE 匯款記錄ID IS NOT NULL GROUP BY 活動編號, 活動名稱, 匯款記錄ID, 匯款人姓名, 匯款人電話, 匯款金額, 入帳日期, 匯款狀態; GO