Fix: Corriger le type PDO dans StripeService et retirer getConnection()

This commit is contained in:
2025-09-01 15:23:48 +02:00
parent f597c9aeb5
commit a548ef8890
545 changed files with 189339 additions and 130108 deletions

View File

@@ -0,0 +1,197 @@
-- =============================================================
-- Tables pour l'intégration Stripe Connect + Terminal
-- Date: 2025-09-01
-- Version: 1.0.0
-- Préfixe: stripe_
-- =============================================================
-- Table pour stocker les comptes Stripe Connect des amicales
CREATE TABLE IF NOT EXISTS stripe_accounts (
id INT(10) UNSIGNED PRIMARY KEY AUTO_INCREMENT,
fk_entite INT(10) UNSIGNED NOT NULL,
stripe_account_id VARCHAR(255) UNIQUE,
stripe_location_id VARCHAR(255),
charges_enabled BOOLEAN DEFAULT FALSE,
payouts_enabled BOOLEAN DEFAULT FALSE,
onboarding_completed BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (fk_entite) REFERENCES entites(id) ON DELETE CASCADE,
INDEX idx_fk_entite (fk_entite),
INDEX idx_stripe_account_id (stripe_account_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Table pour stocker les intentions de paiement
CREATE TABLE IF NOT EXISTS stripe_payment_intents (
id INT(10) UNSIGNED PRIMARY KEY AUTO_INCREMENT,
stripe_payment_intent_id VARCHAR(255) UNIQUE,
fk_entite INT(10) UNSIGNED NOT NULL,
fk_user INT(10) UNSIGNED NOT NULL,
amount INT NOT NULL COMMENT 'Montant en centimes',
currency VARCHAR(3) DEFAULT 'eur',
status VARCHAR(50),
application_fee INT COMMENT 'Commission en centimes',
metadata JSON,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (fk_entite) REFERENCES entites(id) ON DELETE CASCADE,
FOREIGN KEY (fk_user) REFERENCES users(id) ON DELETE CASCADE,
INDEX idx_fk_entite (fk_entite),
INDEX idx_fk_user (fk_user),
INDEX idx_status (status),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Table pour les readers Terminal (Tap to Pay virtuel)
CREATE TABLE IF NOT EXISTS stripe_terminal_readers (
id INT(10) UNSIGNED PRIMARY KEY AUTO_INCREMENT,
stripe_reader_id VARCHAR(255) UNIQUE,
fk_entite INT(10) UNSIGNED NOT NULL,
label VARCHAR(255),
location VARCHAR(255),
status VARCHAR(50),
device_type VARCHAR(50) COMMENT 'ios_tap_to_pay, android_tap_to_pay',
device_info JSON COMMENT 'Infos sur le device (modèle, OS, etc)',
last_seen_at TIMESTAMP NULL,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (fk_entite) REFERENCES entites(id) ON DELETE CASCADE,
INDEX idx_fk_entite (fk_entite),
INDEX idx_device_type (device_type)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Table pour les appareils Android certifiés Tap to Pay
CREATE TABLE IF NOT EXISTS stripe_android_certified_devices (
id INT(10) UNSIGNED PRIMARY KEY AUTO_INCREMENT,
manufacturer VARCHAR(100),
model VARCHAR(200),
model_identifier VARCHAR(200),
tap_to_pay_certified BOOLEAN DEFAULT FALSE,
certification_date DATE,
min_android_version INT,
country VARCHAR(2) DEFAULT 'FR',
notes TEXT,
last_verified TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_manufacturer_model (manufacturer, model),
INDEX idx_certified (tap_to_pay_certified, country),
UNIQUE KEY unique_device (manufacturer, model, model_identifier)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Table pour l'historique des paiements (pour audit et réconciliation)
CREATE TABLE IF NOT EXISTS stripe_payment_history (
id INT(10) UNSIGNED PRIMARY KEY AUTO_INCREMENT,
fk_payment_intent INT(10) UNSIGNED,
event_type VARCHAR(50) COMMENT 'created, processing, succeeded, failed, refunded',
event_data JSON,
webhook_id VARCHAR(255),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
FOREIGN KEY (fk_payment_intent) REFERENCES stripe_payment_intents(id) ON DELETE CASCADE,
INDEX idx_fk_payment_intent (fk_payment_intent),
INDEX idx_event_type (event_type),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Table pour les remboursements
CREATE TABLE IF NOT EXISTS stripe_refunds (
id INT(10) UNSIGNED PRIMARY KEY AUTO_INCREMENT,
stripe_refund_id VARCHAR(255) UNIQUE,
fk_payment_intent INT(10) UNSIGNED NOT NULL,
amount INT NOT NULL COMMENT 'Montant remboursé en centimes',
reason VARCHAR(100) COMMENT 'duplicate, fraudulent, requested_by_customer',
status VARCHAR(50),
metadata JSON,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
FOREIGN KEY (fk_payment_intent) REFERENCES stripe_payment_intents(id) ON DELETE CASCADE,
INDEX idx_fk_payment_intent (fk_payment_intent),
INDEX idx_status (status)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Table pour les webhooks reçus (pour éviter les doublons et debug)
CREATE TABLE IF NOT EXISTS stripe_webhooks (
id INT(10) UNSIGNED PRIMARY KEY AUTO_INCREMENT,
stripe_event_id VARCHAR(255) UNIQUE,
event_type VARCHAR(100),
livemode BOOLEAN DEFAULT FALSE,
payload JSON,
processed BOOLEAN DEFAULT FALSE,
error_message TEXT NULL,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
processed_at TIMESTAMP NULL,
INDEX idx_event_type (event_type),
INDEX idx_processed (processed),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- Insertion des appareils Android certifiés pour Tap to Pay en France
INSERT INTO stripe_android_certified_devices (manufacturer, model, model_identifier, tap_to_pay_certified, min_android_version, certification_date) VALUES
-- Samsung
('Samsung', 'Galaxy S21', 'SM-G991B', TRUE, 11, '2023-01-01'),
('Samsung', 'Galaxy S21+', 'SM-G996B', TRUE, 11, '2023-01-01'),
('Samsung', 'Galaxy S21 Ultra', 'SM-G998B', TRUE, 11, '2023-01-01'),
('Samsung', 'Galaxy S22', 'SM-S901B', TRUE, 12, '2023-01-01'),
('Samsung', 'Galaxy S22+', 'SM-S906B', TRUE, 12, '2023-01-01'),
('Samsung', 'Galaxy S22 Ultra', 'SM-S908B', TRUE, 12, '2023-01-01'),
('Samsung', 'Galaxy S23', 'SM-S911B', TRUE, 13, '2023-06-01'),
('Samsung', 'Galaxy S23+', 'SM-S916B', TRUE, 13, '2023-06-01'),
('Samsung', 'Galaxy S23 Ultra', 'SM-S918B', TRUE, 13, '2023-06-01'),
('Samsung', 'Galaxy S24', 'SM-S921B', TRUE, 14, '2024-01-01'),
('Samsung', 'Galaxy S24+', 'SM-S926B', TRUE, 14, '2024-01-01'),
('Samsung', 'Galaxy S24 Ultra', 'SM-S928B', TRUE, 14, '2024-01-01'),
-- Google Pixel
('Google', 'Pixel 6', 'oriole', TRUE, 12, '2023-01-01'),
('Google', 'Pixel 6 Pro', 'raven', TRUE, 12, '2023-01-01'),
('Google', 'Pixel 6a', 'bluejay', TRUE, 12, '2023-03-01'),
('Google', 'Pixel 7', 'panther', TRUE, 13, '2023-03-01'),
('Google', 'Pixel 7 Pro', 'cheetah', TRUE, 13, '2023-03-01'),
('Google', 'Pixel 7a', 'lynx', TRUE, 13, '2023-06-01'),
('Google', 'Pixel 8', 'shiba', TRUE, 14, '2023-10-01'),
('Google', 'Pixel 8 Pro', 'husky', TRUE, 14, '2023-10-01'),
('Google', 'Pixel Fold', 'felix', TRUE, 13, '2023-07-01'),
-- OnePlus
('OnePlus', '9', 'LE2113', TRUE, 11, '2023-03-01'),
('OnePlus', '9 Pro', 'LE2123', TRUE, 11, '2023-03-01'),
('OnePlus', '10 Pro', 'NE2213', TRUE, 12, '2023-06-01'),
('OnePlus', '11', 'CPH2449', TRUE, 13, '2023-09-01'),
-- Xiaomi
('Xiaomi', 'Mi 11', 'M2011K2G', TRUE, 11, '2023-06-01'),
('Xiaomi', '12', '2201123G', TRUE, 12, '2023-09-01'),
('Xiaomi', '12 Pro', '2201122G', TRUE, 12, '2023-09-01'),
('Xiaomi', '13', '2211133G', TRUE, 13, '2024-01-01'),
('Xiaomi', '13 Pro', '2210132G', TRUE, 13, '2024-01-01');
-- Vue pour faciliter les requêtes de statistiques
CREATE OR REPLACE VIEW v_stripe_payment_stats AS
SELECT
spi.fk_entite,
e.encrypted_name AS entite_name,
spi.fk_user,
u.encrypted_name AS user_nom,
u.first_name AS user_prenom,
COUNT(CASE WHEN spi.status = 'succeeded' THEN 1 END) as total_ventes,
SUM(CASE WHEN spi.status = 'succeeded' THEN spi.amount ELSE 0 END) as total_montant,
SUM(CASE WHEN spi.status = 'succeeded' THEN spi.application_fee ELSE 0 END) as total_commissions,
DATE(spi.created_at) as date_vente
FROM stripe_payment_intents spi
LEFT JOIN entites e ON spi.fk_entite = e.id
LEFT JOIN users u ON spi.fk_user = u.id
GROUP BY spi.fk_entite, spi.fk_user, DATE(spi.created_at);
-- Vue pour le dashboard des amicales
CREATE OR REPLACE VIEW v_stripe_amicale_dashboard AS
SELECT
sa.fk_entite,
e.encrypted_name AS entite_name,
sa.stripe_account_id,
sa.charges_enabled,
sa.payouts_enabled,
COUNT(DISTINCT spi.id) as total_transactions,
SUM(CASE WHEN spi.status = 'succeeded' THEN spi.amount ELSE 0 END) as total_revenus,
SUM(CASE WHEN spi.status = 'succeeded' THEN spi.application_fee ELSE 0 END) as total_frais_plateforme,
MAX(spi.created_at) as derniere_transaction
FROM stripe_accounts sa
LEFT JOIN entites e ON sa.fk_entite = e.id
LEFT JOIN stripe_payment_intents spi ON sa.fk_entite = spi.fk_entite
GROUP BY sa.fk_entite, sa.stripe_account_id;