Skip to content

Commit 89dcb8e

Browse files
committed
wip: Cloudflare D1 implementation
1 parent 978955b commit 89dcb8e

File tree

1 file changed

+172
-0
lines changed

1 file changed

+172
-0
lines changed
Lines changed: 172 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,172 @@
1+
/*
2+
* MIT License
3+
*
4+
* Copyright (c) 2025 Ronan LE MEILLAT
5+
*
6+
* Permission is hereby granted, free of charge, to any person obtaining a copy
7+
* of this software and associated documentation files (the "Software"), to deal
8+
* in the Software without restriction, including without limitation the rights
9+
* to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
10+
* copies of the Software, and to permit persons to whom the Software is
11+
* furnished to do so, subject to the following conditions:
12+
*
13+
* The above copyright notice and this permission notice shall be included in all
14+
* copies or substantial portions of the Software.
15+
*
16+
* THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
17+
* IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
18+
* FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
19+
* AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
20+
* LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
21+
* OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
22+
* SOFTWARE.
23+
*/
24+
25+
-- Activation du mode strict SQLite et des clés étrangères
26+
PRAGMA foreign_keys = ON;
27+
28+
-- Suppression des tables si elles existent déjà (pour réinitialisation)
29+
DROP TABLE IF EXISTS refunds;
30+
DROP TABLE IF EXISTS publications;
31+
DROP TABLE IF EXISTS feedbacks;
32+
DROP TABLE IF EXISTS purchases;
33+
DROP TABLE IF EXISTS id_mappings;
34+
DROP TABLE IF EXISTS testers;
35+
36+
-- Table des testeurs
37+
CREATE TABLE testers (
38+
uuid TEXT PRIMARY KEY,
39+
name TEXT NOT NULL,
40+
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
41+
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
42+
);
43+
44+
-- Table de mapping des IDs OAuth avec les testeurs (relation 1:N)
45+
CREATE TABLE id_mappings (
46+
id TEXT PRIMARY KEY,
47+
tester_uuid TEXT NOT NULL,
48+
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
49+
FOREIGN KEY (tester_uuid) REFERENCES testers(uuid) ON DELETE CASCADE
50+
);
51+
52+
-- Index pour accélérer les recherches de testeur par UUID
53+
CREATE INDEX idx_id_mappings_tester_uuid ON id_mappings(tester_uuid);
54+
55+
-- Table des achats
56+
CREATE TABLE purchases (
57+
id TEXT PRIMARY KEY,
58+
tester_uuid TEXT NOT NULL,
59+
date TEXT NOT NULL, -- Format YYYY-MM-DD
60+
order_number TEXT NOT NULL,
61+
description TEXT NOT NULL,
62+
amount REAL NOT NULL,
63+
screenshot TEXT NOT NULL, -- Base64 encoded image
64+
refunded BOOLEAN DEFAULT 0,
65+
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
66+
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
67+
FOREIGN KEY (tester_uuid) REFERENCES testers(uuid) ON DELETE CASCADE
68+
);
69+
70+
-- Index pour les recherches d'achats par testeur
71+
CREATE INDEX idx_purchases_tester_uuid ON purchases(tester_uuid);
72+
-- Index pour les recherches d'achats remboursés/non-remboursés
73+
CREATE INDEX idx_purchases_refunded ON purchases(refunded);
74+
75+
-- Table des feedbacks
76+
CREATE TABLE feedbacks (
77+
id INTEGER PRIMARY KEY AUTOINCREMENT,
78+
purchase_id TEXT NOT NULL UNIQUE, -- Relation 1:1 avec purchase
79+
date TEXT NOT NULL, -- Format YYYY-MM-DD
80+
feedback TEXT NOT NULL,
81+
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
82+
FOREIGN KEY (purchase_id) REFERENCES purchases(id) ON DELETE CASCADE
83+
);
84+
85+
-- Table des publications
86+
CREATE TABLE publications (
87+
id INTEGER PRIMARY KEY AUTOINCREMENT,
88+
purchase_id TEXT NOT NULL UNIQUE, -- Relation 1:1 avec purchase
89+
date TEXT NOT NULL, -- Format YYYY-MM-DD
90+
screenshot TEXT NOT NULL, -- Base64 encoded image
91+
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
92+
FOREIGN KEY (purchase_id) REFERENCES purchases(id) ON DELETE CASCADE
93+
);
94+
95+
-- Table des remboursements
96+
CREATE TABLE refunds (
97+
id INTEGER PRIMARY KEY AUTOINCREMENT,
98+
purchase_id TEXT NOT NULL UNIQUE, -- Relation 1:1 avec purchase
99+
date TEXT NOT NULL, -- Format YYYY-MM-DD (date d'enregistrement)
100+
refund_date TEXT NOT NULL, -- Format YYYY-MM-DD (date effective du remboursement)
101+
amount REAL NOT NULL,
102+
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
103+
FOREIGN KEY (purchase_id) REFERENCES purchases(id) ON DELETE CASCADE
104+
);
105+
106+
-- Trigger pour mettre à jour le statut "refunded" d'un achat après l'ajout d'un remboursement
107+
CREATE TRIGGER update_purchase_refunded_status
108+
AFTER INSERT ON refunds
109+
BEGIN
110+
UPDATE purchases SET refunded = 1, updated_at = CURRENT_TIMESTAMP WHERE id = NEW.purchase_id;
111+
END;
112+
113+
-- Trigger pour mettre à jour le timestamp lors de la modification d'un testeur
114+
CREATE TRIGGER update_tester_timestamp
115+
AFTER UPDATE ON testers
116+
BEGIN
117+
UPDATE testers SET updated_at = CURRENT_TIMESTAMP WHERE uuid = NEW.uuid;
118+
END;
119+
120+
-- Trigger pour mettre à jour le timestamp lors de la modification d'un achat
121+
CREATE TRIGGER update_purchase_timestamp
122+
AFTER UPDATE ON purchases
123+
BEGIN
124+
UPDATE purchases SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id;
125+
END;
126+
127+
-- Vue pour obtenir facilement les achats avec leur statut de feedback, publication et remboursement
128+
CREATE VIEW purchase_status AS
129+
SELECT
130+
p.id,
131+
p.tester_uuid,
132+
p.date,
133+
p.order_number,
134+
p.description,
135+
p.amount,
136+
p.refunded,
137+
CASE WHEN f.id IS NOT NULL THEN 1 ELSE 0 END as has_feedback,
138+
CASE WHEN pub.id IS NOT NULL THEN 1 ELSE 0 END as has_publication,
139+
CASE WHEN r.id IS NOT NULL THEN 1 ELSE 0 END as has_refund
140+
FROM
141+
purchases p
142+
LEFT JOIN feedbacks f ON p.id = f.purchase_id
143+
LEFT JOIN publications pub ON p.id = pub.purchase_id
144+
LEFT JOIN refunds r ON p.id = r.purchase_id;
145+
146+
-- Vue pour obtenir des statistiques par testeur
147+
CREATE VIEW tester_statistics AS
148+
SELECT
149+
t.uuid,
150+
t.name,
151+
COUNT(p.id) as total_purchases,
152+
SUM(CASE WHEN p.refunded = 1 THEN 1 ELSE 0 END) as refunded_purchases,
153+
SUM(CASE WHEN f.id IS NOT NULL THEN 1 ELSE 0 END) as purchases_with_feedback,
154+
SUM(CASE WHEN pub.id IS NOT NULL THEN 1 ELSE 0 END) as published_feedbacks,
155+
SUM(p.amount) as total_spent,
156+
SUM(CASE WHEN r.id IS NOT NULL THEN r.amount ELSE 0 END) as total_refunded
157+
FROM
158+
testers t
159+
LEFT JOIN purchases p ON t.uuid = p.tester_uuid
160+
LEFT JOIN feedbacks f ON p.id = f.purchase_id
161+
LEFT JOIN publications pub ON p.id = pub.purchase_id
162+
LEFT JOIN refunds r ON p.id = r.purchase_id
163+
GROUP BY t.uuid;
164+
165+
-- -- Insérer des données de test (optionnel)
166+
-- INSERT INTO testers (uuid, name) VALUES
167+
-- ('45f9830a-309b-4cda-95ec-71e000b78f7d', 'John Doe'),
168+
-- ('cc97a5cc-c4ba-4804-98b5-90532f09bd83', 'Jane Doe');
169+
170+
-- INSERT INTO id_mappings (id, tester_uuid) VALUES
171+
-- ('auth0|1234567890', '45f9830a-309b-4cda-95ec-71e000b78f7d'),
172+
-- ('auth0|0987654321', 'cc97a5cc-c4ba-4804-98b5-90532f09bd83');

0 commit comments

Comments
 (0)