V1__Initial_schema.sql
4.51 KB
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
-- 创建 payments 表(根据 Payment.java 实体类)
CREATE TABLE payments (
    id BIGSERIAL PRIMARY KEY,
    payment_id VARCHAR(255) UNIQUE NOT NULL,
    order_id VARCHAR(255) NOT NULL,
    order_number VARCHAR(255),
    user_id BIGINT NOT NULL,
    amount NUMERIC(12,2) NOT NULL,
    currency VARCHAR(10) NOT NULL DEFAULT 'USD',
    status VARCHAR(50) NOT NULL DEFAULT 'PENDING', -- PENDING, PROCESSING, SUCCEEDED, FAILED, CANCELLED, REFUNDED
    payment_method VARCHAR(50) NOT NULL, -- STRIPE, PAYPAL, CREDIT_CARD, BANK_TRANSFER
    payment_gateway VARCHAR(50), -- STRIPE, PAYPAL
    gateway_payment_id VARCHAR(255),
    gateway_customer_id VARCHAR(255),
    description TEXT,
    failure_reason TEXT,
    failure_code VARCHAR(255),
    metadata TEXT,
    
    -- 时间戳字段
    created_at TIMESTAMP,
    updated_at TIMESTAMP,
    processed_at TIMESTAMP,
    refunded_at TIMESTAMP,
    
    -- 版本控制
    version INTEGER DEFAULT 0
);
-- 创建 payment_methods 表(根据 PaymentMethod.java 实体类)
CREATE TABLE payment_methods (
    id BIGSERIAL PRIMARY KEY,
    user_id BIGINT NOT NULL,
    payment_method_id VARCHAR(255) NOT NULL,
    type VARCHAR(50) NOT NULL, -- CARD, PAYPAL, BANK_ACCOUNT
    gateway VARCHAR(50) NOT NULL, -- STRIPE, PAYPAL
    gateway_customer_id VARCHAR(255),
    last_four VARCHAR(4),
    brand VARCHAR(50),
    exp_month INTEGER,
    exp_year INTEGER,
    is_default BOOLEAN DEFAULT false,
    is_active BOOLEAN DEFAULT true,
    metadata TEXT,
    created_at TIMESTAMP,
    updated_at TIMESTAMP
);
-- 创建 payment_events 表(支付事件历史)
CREATE TABLE payment_events (
    id BIGSERIAL PRIMARY KEY,
    payment_id BIGINT NOT NULL,
    event_type VARCHAR(100) NOT NULL, -- payment.created, payment.succeeded, payment.failed, refund.created, etc.
    event_data TEXT,
    gateway_event_id VARCHAR(255), -- Event ID from payment gateway
    created_at TIMESTAMP NOT NULL,
    
    FOREIGN KEY (payment_id) REFERENCES payments(id) ON DELETE CASCADE
);
-- 创建 refunds 表(根据 Refund.java 实体类)- 已包含 user_id 字段
CREATE TABLE refunds (
    id BIGSERIAL PRIMARY KEY,
    refund_id VARCHAR(255) UNIQUE NOT NULL,
    payment_id BIGINT NOT NULL,
    user_id BIGINT NOT NULL,
    amount NUMERIC(12,2) NOT NULL,
    currency VARCHAR(10) NOT NULL DEFAULT 'USD',
    status VARCHAR(50) NOT NULL DEFAULT 'PENDING', -- PENDING, PROCESSING, SUCCEEDED, FAILED, CANCELLED
    reason TEXT,
    gateway_refund_id VARCHAR(255),
    gateway_transaction_id VARCHAR(255),
    failure_reason TEXT,
    failure_code VARCHAR(255),
    metadata TEXT,
    created_at TIMESTAMP,
    updated_at TIMESTAMP,
    processed_at TIMESTAMP,
    refunded_at TIMESTAMP,
    
    FOREIGN KEY (payment_id) REFERENCES payments(id) ON DELETE CASCADE
);
-- 创建索引
-- payments 表索引
CREATE INDEX idx_payments_payment_id ON payments(payment_id);
CREATE INDEX idx_payments_order_id ON payments(order_id);
CREATE INDEX idx_payments_order_number ON payments(order_number);
CREATE INDEX idx_payments_status ON payments(status);
CREATE INDEX idx_payments_payment_method ON payments(payment_method);
CREATE INDEX idx_payments_gateway_payment_id ON payments(gateway_payment_id);
CREATE INDEX idx_payments_created_at ON payments(created_at);
CREATE INDEX idx_payments_user_id ON payments(user_id);
-- payment_methods 表索引
CREATE INDEX idx_payment_methods_user_id ON payment_methods(user_id);
CREATE INDEX idx_payment_methods_payment_method_id ON payment_methods(payment_method_id);
CREATE INDEX idx_payment_methods_gateway_customer_id ON payment_methods(gateway_customer_id);
CREATE INDEX idx_payment_methods_is_default ON payment_methods(is_default);
CREATE INDEX idx_payment_methods_is_active ON payment_methods(is_active);
-- payment_events 表索引
CREATE INDEX idx_payment_events_payment_id ON payment_events(payment_id);
CREATE INDEX idx_payment_events_event_type ON payment_events(event_type);
CREATE INDEX idx_payment_events_created_at ON payment_events(created_at);
-- refunds 表索引
CREATE INDEX idx_refunds_refund_id ON refunds(refund_id);
CREATE INDEX idx_refunds_payment_id ON refunds(payment_id);
CREATE INDEX idx_refunds_user_id ON refunds(user_id);
CREATE INDEX idx_refunds_status ON refunds(status);
CREATE INDEX idx_refunds_created_at ON refunds(created_at);
CREATE INDEX idx_refunds_user_id_created_at ON refunds(user_id, created_at);
-- 插入初始数据(可选)
-- INSERT INTO payments (payment_id, order_id, user_id, amount, currency, status, payment_method) 
-- VALUES ('PAY001', 'ORDER001', 1, 100.00, 'USD', 'SUCCEEDED', 'STRIPE');