summaryrefslogtreecommitdiff
path: root/src/database.rs
blob: 5251dacf0c46c51cad0cf987fb18b4112cc8c7b7 (plain)
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
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
use anyhow::Result;
use chrono::{DateTime, Utc};
use rusqlite::{Connection, params};
use serde::{Deserialize, Serialize};
use std::path::Path;

#[derive(Debug, Clone, Serialize, Deserialize)]
pub struct DbOAuthClient {
    pub id: i64,
    pub client_id: String,
    pub client_secret_hash: String,
    pub client_name: String,
    pub redirect_uris: String,  // JSON array
    pub scopes: String,         // Space-separated
    pub grant_types: String,    // Space-separated
    pub response_types: String, // Space-separated
    pub created_at: DateTime<Utc>,
    pub updated_at: DateTime<Utc>,
    pub is_active: bool,
}

#[derive(Debug, Clone, Serialize, Deserialize)]
pub struct DbAuthCode {
    pub id: i64,
    pub code: String,
    pub client_id: String,
    pub user_id: String,
    pub redirect_uri: String,
    pub scope: Option<String>,
    pub expires_at: DateTime<Utc>,
    pub created_at: DateTime<Utc>,
    pub is_used: bool,
    // PKCE fields
    pub code_challenge: Option<String>,
    pub code_challenge_method: Option<String>,
}

#[derive(Debug, Clone, Serialize, Deserialize)]
pub struct DbAccessToken {
    pub id: i64,
    pub token_id: String,
    pub client_id: String,
    pub user_id: String,
    pub scope: Option<String>,
    pub expires_at: DateTime<Utc>,
    pub created_at: DateTime<Utc>,
    pub is_revoked: bool,
    pub token_hash: String, // For revocation lookup
}

#[derive(Debug, Clone, Serialize, Deserialize)]
pub struct DbRefreshToken {
    pub id: i64,
    pub token_id: String,
    pub access_token_id: i64,
    pub client_id: String,
    pub user_id: String,
    pub scope: Option<String>,
    pub expires_at: DateTime<Utc>,
    pub created_at: DateTime<Utc>,
    pub is_revoked: bool,
    pub token_hash: String,
}

#[derive(Debug, Clone, Serialize, Deserialize)]
pub struct DbRsaKey {
    pub id: i64,
    pub kid: String,
    pub private_key_pem: String,
    pub public_key_pem: String,
    pub created_at: DateTime<Utc>,
    pub is_current: bool,
}

#[derive(Debug, Clone, Serialize, Deserialize)]
pub struct DbAuditLog {
    pub id: i64,
    pub event_type: String,
    pub client_id: Option<String>,
    pub user_id: Option<String>,
    pub ip_address: Option<String>,
    pub user_agent: Option<String>,
    pub details: Option<String>, // JSON
    pub created_at: DateTime<Utc>,
    pub success: bool,
}

#[derive(Debug, Clone, Serialize, Deserialize)]
pub struct DbRateLimit {
    pub id: i64,
    pub identifier: String, // client_id or IP address
    pub endpoint: String,
    pub count: i32,
    pub window_start: DateTime<Utc>,
    pub created_at: DateTime<Utc>,
}

pub struct Database {
    conn: Connection,
}

impl Database {
    pub fn new<P: AsRef<Path>>(path: P) -> Result<Self> {
        let conn = Connection::open(path)?;
        let db = Self { conn };
        db.initialize_schema()?;
        Ok(db)
    }

    pub fn new_in_memory() -> Result<Self> {
        let conn = Connection::open_in_memory()?;
        let db = Self { conn };
        db.initialize_schema()?;
        Ok(db)
    }

    fn initialize_schema(&self) -> Result<()> {
        // OAuth Clients table
        self.conn.execute(
            "CREATE TABLE IF NOT EXISTS oauth_clients (
                id INTEGER PRIMARY KEY AUTOINCREMENT,
                client_id TEXT NOT NULL UNIQUE,
                client_secret_hash TEXT NOT NULL,
                client_name TEXT NOT NULL,
                redirect_uris TEXT NOT NULL, -- JSON array
                scopes TEXT NOT NULL, -- space-separated
                grant_types TEXT NOT NULL, -- space-separated  
                response_types TEXT NOT NULL, -- space-separated
                created_at TEXT NOT NULL,
                updated_at TEXT NOT NULL,
                is_active BOOLEAN NOT NULL DEFAULT 1
            )",
            [],
        )?;

        // Authorization Codes table
        self.conn.execute(
            "CREATE TABLE IF NOT EXISTS auth_codes (
                id INTEGER PRIMARY KEY AUTOINCREMENT,
                code TEXT NOT NULL UNIQUE,
                client_id TEXT NOT NULL,
                user_id TEXT NOT NULL,
                redirect_uri TEXT NOT NULL,
                scope TEXT,
                expires_at TEXT NOT NULL,
                created_at TEXT NOT NULL,
                is_used BOOLEAN NOT NULL DEFAULT 0,
                code_challenge TEXT,
                code_challenge_method TEXT,
                FOREIGN KEY (client_id) REFERENCES oauth_clients (client_id)
            )",
            [],
        )?;

        // Access Tokens table
        self.conn.execute(
            "CREATE TABLE IF NOT EXISTS access_tokens (
                id INTEGER PRIMARY KEY AUTOINCREMENT,
                token_id TEXT NOT NULL UNIQUE,
                client_id TEXT NOT NULL,
                user_id TEXT NOT NULL,
                scope TEXT,
                expires_at TEXT NOT NULL,
                created_at TEXT NOT NULL,
                is_revoked BOOLEAN NOT NULL DEFAULT 0,
                token_hash TEXT NOT NULL,
                FOREIGN KEY (client_id) REFERENCES oauth_clients (client_id)
            )",
            [],
        )?;

        // Refresh Tokens table
        self.conn.execute(
            "CREATE TABLE IF NOT EXISTS refresh_tokens (
                id INTEGER PRIMARY KEY AUTOINCREMENT,
                token_id TEXT NOT NULL UNIQUE,
                access_token_id INTEGER NOT NULL,
                client_id TEXT NOT NULL,
                user_id TEXT NOT NULL,
                scope TEXT,
                expires_at TEXT NOT NULL,
                created_at TEXT NOT NULL,
                is_revoked BOOLEAN NOT NULL DEFAULT 0,
                token_hash TEXT NOT NULL,
                FOREIGN KEY (client_id) REFERENCES oauth_clients (client_id),
                FOREIGN KEY (access_token_id) REFERENCES access_tokens (id)
            )",
            [],
        )?;

        // RSA Keys table
        self.conn.execute(
            "CREATE TABLE IF NOT EXISTS rsa_keys (
                id INTEGER PRIMARY KEY AUTOINCREMENT,
                kid TEXT NOT NULL UNIQUE,
                private_key_pem TEXT NOT NULL,
                public_key_pem TEXT NOT NULL,
                created_at TEXT NOT NULL,
                is_current BOOLEAN NOT NULL DEFAULT 0
            )",
            [],
        )?;

        // Audit Log table
        self.conn.execute(
            "CREATE TABLE IF NOT EXISTS audit_logs (
                id INTEGER PRIMARY KEY AUTOINCREMENT,
                event_type TEXT NOT NULL,
                client_id TEXT,
                user_id TEXT,
                ip_address TEXT,
                user_agent TEXT,
                details TEXT, -- JSON
                created_at TEXT NOT NULL,
                success BOOLEAN NOT NULL
            )",
            [],
        )?;

        // Rate Limiting table
        self.conn.execute(
            "CREATE TABLE IF NOT EXISTS rate_limits (
                id INTEGER PRIMARY KEY AUTOINCREMENT,
                identifier TEXT NOT NULL, -- client_id or IP
                endpoint TEXT NOT NULL,
                count INTEGER NOT NULL DEFAULT 1,
                window_start TEXT NOT NULL,
                created_at TEXT NOT NULL,
                UNIQUE (identifier, endpoint, window_start)
            )",
            [],
        )?;

        // Create indexes for performance
        self.conn.execute(
            "CREATE INDEX IF NOT EXISTS idx_auth_codes_client_id ON auth_codes (client_id)",
            [],
        )?;
        self.conn.execute(
            "CREATE INDEX IF NOT EXISTS idx_auth_codes_expires_at ON auth_codes (expires_at)",
            [],
        )?;
        self.conn.execute(
            "CREATE INDEX IF NOT EXISTS idx_access_tokens_client_id ON access_tokens (client_id)",
            [],
        )?;
        self.conn.execute(
            "CREATE INDEX IF NOT EXISTS idx_access_tokens_expires_at ON access_tokens (expires_at)",
            [],
        )?;
        self.conn.execute(
            "CREATE INDEX IF NOT EXISTS idx_refresh_tokens_client_id ON refresh_tokens (client_id)",
            [],
        )?;
        self.conn.execute(
            "CREATE INDEX IF NOT EXISTS idx_audit_logs_created_at ON audit_logs (created_at)",
            [],
        )?;
        self.conn.execute(
            "CREATE INDEX IF NOT EXISTS idx_rate_limits_identifier ON rate_limits (identifier, endpoint)",
            [],
        )?;

        Ok(())
    }

    // OAuth Client operations
    pub fn create_oauth_client(&self, client: &DbOAuthClient) -> Result<i64> {
        let mut stmt = self.conn.prepare(
            "INSERT INTO oauth_clients 
             (client_id, client_secret_hash, client_name, redirect_uris, scopes, 
              grant_types, response_types, created_at, updated_at, is_active)
             VALUES (?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10)",
        )?;

        let id = stmt.insert(params![
            client.client_id,
            client.client_secret_hash,
            client.client_name,
            client.redirect_uris,
            client.scopes,
            client.grant_types,
            client.response_types,
            client.created_at.to_rfc3339(),
            client.updated_at.to_rfc3339(),
            client.is_active
        ])?;

        Ok(id)
    }

    pub fn get_oauth_client(&self, client_id: &str) -> Result<Option<DbOAuthClient>> {
        let mut stmt = self.conn.prepare(
            "SELECT id, client_id, client_secret_hash, client_name, redirect_uris, 
                    scopes, grant_types, response_types, created_at, updated_at, is_active
             FROM oauth_clients WHERE client_id = ?1 AND is_active = 1",
        )?;

        let client = stmt.query_row([client_id], |row| {
            Ok(DbOAuthClient {
                id: row.get(0)?,
                client_id: row.get(1)?,
                client_secret_hash: row.get(2)?,
                client_name: row.get(3)?,
                redirect_uris: row.get(4)?,
                scopes: row.get(5)?,
                grant_types: row.get(6)?,
                response_types: row.get(7)?,
                created_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(8)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            8,
                            "created_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                updated_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(9)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            9,
                            "updated_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                is_active: row.get(10)?,
            })
        });

        match client {
            Ok(client) => Ok(Some(client)),
            Err(rusqlite::Error::QueryReturnedNoRows) => Ok(None),
            Err(e) => Err(e.into()),
        }
    }

    // Authorization Code operations
    pub fn create_auth_code(&self, auth_code: &DbAuthCode) -> Result<i64> {
        let mut stmt = self.conn.prepare(
            "INSERT INTO auth_codes 
             (code, client_id, user_id, redirect_uri, scope, expires_at, created_at, 
              is_used, code_challenge, code_challenge_method)
             VALUES (?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8, ?9, ?10)",
        )?;

        let id = stmt.insert(params![
            auth_code.code,
            auth_code.client_id,
            auth_code.user_id,
            auth_code.redirect_uri,
            auth_code.scope,
            auth_code.expires_at.to_rfc3339(),
            auth_code.created_at.to_rfc3339(),
            auth_code.is_used,
            auth_code.code_challenge,
            auth_code.code_challenge_method
        ])?;

        Ok(id)
    }

    pub fn get_auth_code(&self, code: &str) -> Result<Option<DbAuthCode>> {
        let mut stmt = self.conn.prepare(
            "SELECT id, code, client_id, user_id, redirect_uri, scope, expires_at, 
                    created_at, is_used, code_challenge, code_challenge_method
             FROM auth_codes WHERE code = ?1",
        )?;

        let auth_code = stmt.query_row([code], |row| {
            Ok(DbAuthCode {
                id: row.get(0)?,
                code: row.get(1)?,
                client_id: row.get(2)?,
                user_id: row.get(3)?,
                redirect_uri: row.get(4)?,
                scope: row.get(5)?,
                expires_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(6)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            6,
                            "expires_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                created_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(7)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            7,
                            "created_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                is_used: row.get(8)?,
                code_challenge: row.get(9)?,
                code_challenge_method: row.get(10)?,
            })
        });

        match auth_code {
            Ok(code) => Ok(Some(code)),
            Err(rusqlite::Error::QueryReturnedNoRows) => Ok(None),
            Err(e) => Err(e.into()),
        }
    }

    pub fn mark_auth_code_used(&self, code: &str) -> Result<()> {
        self.conn
            .execute("UPDATE auth_codes SET is_used = 1 WHERE code = ?1", [code])?;
        Ok(())
    }

    // Access Token operations
    pub fn create_access_token(&self, token: &DbAccessToken) -> Result<i64> {
        let mut stmt = self.conn.prepare(
            "INSERT INTO access_tokens 
             (token_id, client_id, user_id, scope, expires_at, created_at, is_revoked, token_hash)
             VALUES (?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8)",
        )?;

        let id = stmt.insert(params![
            token.token_id,
            token.client_id,
            token.user_id,
            token.scope,
            token.expires_at.to_rfc3339(),
            token.created_at.to_rfc3339(),
            token.is_revoked,
            token.token_hash
        ])?;

        Ok(id)
    }

    pub fn get_access_token(&self, token_hash: &str) -> Result<Option<DbAccessToken>> {
        let mut stmt = self.conn.prepare(
            "SELECT id, token_id, client_id, user_id, scope, expires_at, created_at, is_revoked, token_hash
             FROM access_tokens WHERE token_hash = ?1"
        )?;

        let token = stmt.query_row([token_hash], |row| {
            Ok(DbAccessToken {
                id: row.get(0)?,
                token_id: row.get(1)?,
                client_id: row.get(2)?,
                user_id: row.get(3)?,
                scope: row.get(4)?,
                expires_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(5)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            5,
                            "expires_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                created_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(6)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            6,
                            "created_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                is_revoked: row.get(7)?,
                token_hash: row.get(8)?,
            })
        });

        match token {
            Ok(token) => Ok(Some(token)),
            Err(rusqlite::Error::QueryReturnedNoRows) => Ok(None),
            Err(e) => Err(e.into()),
        }
    }

    pub fn revoke_access_token(&self, token_hash: &str) -> Result<()> {
        self.conn.execute(
            "UPDATE access_tokens SET is_revoked = 1 WHERE token_hash = ?1",
            [token_hash],
        )?;
        Ok(())
    }

    // RSA Key operations
    pub fn create_rsa_key(&self, key: &DbRsaKey) -> Result<i64> {
        let mut stmt = self.conn.prepare(
            "INSERT INTO rsa_keys (kid, private_key_pem, public_key_pem, created_at, is_current)
             VALUES (?1, ?2, ?3, ?4, ?5)",
        )?;

        let id = stmt.insert(params![
            key.kid,
            key.private_key_pem,
            key.public_key_pem,
            key.created_at.to_rfc3339(),
            key.is_current
        ])?;

        Ok(id)
    }

    pub fn get_current_rsa_key(&self) -> Result<Option<DbRsaKey>> {
        let mut stmt = self.conn.prepare(
            "SELECT id, kid, private_key_pem, public_key_pem, created_at, is_current
             FROM rsa_keys WHERE is_current = 1 ORDER BY created_at DESC LIMIT 1",
        )?;

        let key = stmt.query_row([], |row| {
            Ok(DbRsaKey {
                id: row.get(0)?,
                kid: row.get(1)?,
                private_key_pem: row.get(2)?,
                public_key_pem: row.get(3)?,
                created_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(4)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            4,
                            "created_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                is_current: row.get(5)?,
            })
        });

        match key {
            Ok(key) => Ok(Some(key)),
            Err(rusqlite::Error::QueryReturnedNoRows) => Ok(None),
            Err(e) => Err(e.into()),
        }
    }

    pub fn get_all_rsa_keys(&self) -> Result<Vec<DbRsaKey>> {
        let mut stmt = self.conn.prepare(
            "SELECT id, kid, private_key_pem, public_key_pem, created_at, is_current
             FROM rsa_keys ORDER BY created_at DESC",
        )?;

        let keys = stmt.query_map([], |row| {
            Ok(DbRsaKey {
                id: row.get(0)?,
                kid: row.get(1)?,
                private_key_pem: row.get(2)?,
                public_key_pem: row.get(3)?,
                created_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(4)?)
                    .map_err(|_| {
                        rusqlite::Error::InvalidColumnType(
                            4,
                            "created_at".to_string(),
                            rusqlite::types::Type::Text,
                        )
                    })?
                    .with_timezone(&Utc),
                is_current: row.get(5)?,
            })
        })?;

        let mut result = Vec::new();
        for key in keys {
            result.push(key?);
        }
        Ok(result)
    }

    pub fn set_current_rsa_key(&self, kid: &str) -> Result<()> {
        // First, unset all current keys
        self.conn
            .execute("UPDATE rsa_keys SET is_current = 0", [])?;

        // Then set the specified key as current
        self.conn
            .execute("UPDATE rsa_keys SET is_current = 1 WHERE kid = ?1", [kid])?;

        Ok(())
    }

    // Audit Log operations
    pub fn create_audit_log(&self, log: &DbAuditLog) -> Result<i64> {
        let mut stmt = self.conn.prepare(
            "INSERT INTO audit_logs 
             (event_type, client_id, user_id, ip_address, user_agent, details, created_at, success)
             VALUES (?1, ?2, ?3, ?4, ?5, ?6, ?7, ?8)",
        )?;

        let id = stmt.insert(params![
            log.event_type,
            log.client_id,
            log.user_id,
            log.ip_address,
            log.user_agent,
            log.details,
            log.created_at.to_rfc3339(),
            log.success
        ])?;

        Ok(id)
    }

    // Rate Limiting operations
    pub fn increment_rate_limit(
        &self,
        identifier: &str,
        endpoint: &str,
        window_minutes: i32,
    ) -> Result<i32> {
        let now = Utc::now();
        let window_start = now - chrono::Duration::minutes(window_minutes as i64);

        // Try to increment existing counter in current window
        let affected = self.conn.execute(
            "UPDATE rate_limits SET count = count + 1 
             WHERE identifier = ?1 AND endpoint = ?2 AND window_start >= ?3",
            params![identifier, endpoint, window_start.to_rfc3339()],
        )?;

        if affected == 0 {
            // No existing record, create new one
            self.conn.execute(
                "INSERT OR REPLACE INTO rate_limits (identifier, endpoint, count, window_start, created_at)
                 VALUES (?1, ?2, 1, ?3, ?4)",
                params![identifier, endpoint, now.to_rfc3339(), now.to_rfc3339()],
            )?;
            Ok(1)
        } else {
            // Return current count
            let count: i32 = self.conn.query_row(
                "SELECT count FROM rate_limits 
                 WHERE identifier = ?1 AND endpoint = ?2 AND window_start >= ?3",
                params![identifier, endpoint, window_start.to_rfc3339()],
                |row| row.get(0),
            )?;
            Ok(count)
        }
    }

    // Cleanup operations
    pub fn cleanup_expired_codes(&self) -> Result<usize> {
        let now = Utc::now();
        let affected = self.conn.execute(
            "DELETE FROM auth_codes WHERE expires_at < ?1",
            [now.to_rfc3339()],
        )?;
        Ok(affected)
    }

    pub fn cleanup_expired_tokens(&self) -> Result<usize> {
        let now = Utc::now();
        let affected = self.conn.execute(
            "DELETE FROM access_tokens WHERE expires_at < ?1 AND is_revoked = 1",
            [now.to_rfc3339()],
        )?;
        Ok(affected)
    }

    pub fn cleanup_old_audit_logs(&self, days: i32) -> Result<usize> {
        let cutoff = Utc::now() - chrono::Duration::days(days as i64);
        let affected = self.conn.execute(
            "DELETE FROM audit_logs WHERE created_at < ?1",
            [cutoff.to_rfc3339()],
        )?;
        Ok(affected)
    }

    // Additional methods needed for repository patterns
    pub fn update_oauth_client(&self, client: &DbOAuthClient) -> Result<()> {
        self.conn.execute(
            "UPDATE oauth_clients SET 
             client_secret_hash = ?2, client_name = ?3, redirect_uris = ?4, 
             scopes = ?5, grant_types = ?6, response_types = ?7, 
             updated_at = ?8, is_active = ?9
             WHERE client_id = ?1",
            params![
                client.client_id,
                client.client_secret_hash,
                client.client_name,
                client.redirect_uris,
                client.scopes,
                client.grant_types,
                client.response_types,
                client.updated_at.to_rfc3339(),
                client.is_active
            ],
        )?;
        Ok(())
    }

    pub fn delete_oauth_client(&self, client_id: &str) -> Result<()> {
        self.conn.execute(
            "DELETE FROM oauth_clients WHERE client_id = ?1",
            [client_id],
        )?;
        Ok(())
    }

    pub fn list_oauth_clients(&self) -> Result<Vec<DbOAuthClient>> {
        let mut stmt = self.conn.prepare(
            "SELECT id, client_id, client_secret_hash, client_name, redirect_uris, 
             scopes, grant_types, response_types, created_at, updated_at, is_active
             FROM oauth_clients ORDER BY created_at DESC",
        )?;

        let clients = stmt
            .query_map([], |row| {
                Ok(DbOAuthClient {
                    id: row.get(0)?,
                    client_id: row.get(1)?,
                    client_secret_hash: row.get(2)?,
                    client_name: row.get(3)?,
                    redirect_uris: row.get(4)?,
                    scopes: row.get(5)?,
                    grant_types: row.get(6)?,
                    response_types: row.get(7)?,
                    created_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(8)?)
                        .map_err(|e| {
                            rusqlite::Error::FromSqlConversionFailure(
                                8,
                                rusqlite::types::Type::Text,
                                Box::new(e),
                            )
                        })?
                        .with_timezone(&Utc),
                    updated_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(9)?)
                        .map_err(|e| {
                            rusqlite::Error::FromSqlConversionFailure(
                                9,
                                rusqlite::types::Type::Text,
                                Box::new(e),
                            )
                        })?
                        .with_timezone(&Utc),
                    is_active: row.get(10)?,
                })
            })?
            .collect::<Result<Vec<_>, _>>()?;

        Ok(clients)
    }

    pub fn get_audit_logs(&self, limit: i32) -> Result<Vec<DbAuditLog>> {
        let mut stmt = self.conn.prepare(
            "SELECT id, event_type, client_id, user_id, ip_address, user_agent, details, created_at, success
             FROM audit_logs ORDER BY created_at DESC LIMIT ?1"
        )?;

        let logs = stmt
            .query_map([limit], |row| {
                Ok(DbAuditLog {
                    id: row.get(0)?,
                    event_type: row.get(1)?,
                    client_id: row.get(2)?,
                    user_id: row.get(3)?,
                    ip_address: row.get(4)?,
                    user_agent: row.get(5)?,
                    details: row.get(6)?,
                    created_at: DateTime::parse_from_rfc3339(&row.get::<_, String>(7)?)
                        .map_err(|e| {
                            rusqlite::Error::FromSqlConversionFailure(
                                7,
                                rusqlite::types::Type::Text,
                                Box::new(e),
                            )
                        })?
                        .with_timezone(&Utc),
                    success: row.get(8)?,
                })
            })?
            .collect::<Result<Vec<_>, _>>()?;

        Ok(logs)
    }

    pub fn cleanup_old_rate_limits(&self) -> Result<()> {
        let cutoff = Utc::now() - chrono::Duration::hours(24); // Clean up rate limits older than 24 hours
        self.conn.execute(
            "DELETE FROM rate_limits WHERE created_at < ?1",
            [cutoff.to_rfc3339()],
        )?;
        Ok(())
    }
}

#[cfg(test)]
mod tests {
    use super::*;

    #[test]
    fn test_database_creation() {
        let _db = Database::new_in_memory().expect("Failed to create database");
        assert!(true); // If we got here, database was created successfully
    }

    #[test]
    fn test_oauth_client_operations() {
        let db = Database::new_in_memory().expect("Failed to create database");

        let client = DbOAuthClient {
            id: 0,
            client_id: "test_client".to_string(),
            client_secret_hash: "hash123".to_string(),
            client_name: "Test Client".to_string(),
            redirect_uris: "[\"http://localhost:3000/callback\"]".to_string(),
            scopes: "openid profile".to_string(),
            grant_types: "authorization_code".to_string(),
            response_types: "code".to_string(),
            created_at: Utc::now(),
            updated_at: Utc::now(),
            is_active: true,
        };

        let id = db
            .create_oauth_client(&client)
            .expect("Failed to create client");
        assert!(id > 0);

        let retrieved = db
            .get_oauth_client("test_client")
            .expect("Failed to get client");
        assert!(retrieved.is_some());
        assert_eq!(retrieved.unwrap().client_name, "Test Client");
    }

    #[test]
    fn test_auth_code_operations() {
        let db = Database::new_in_memory().expect("Failed to create database");

        // First create a client (required for foreign key constraint)
        let client = DbOAuthClient {
            id: 0,
            client_id: "test_client".to_string(),
            client_secret_hash: "hash123".to_string(),
            client_name: "Test Client".to_string(),
            redirect_uris: "[\"http://localhost:3000/callback\"]".to_string(),
            scopes: "openid profile".to_string(),
            grant_types: "authorization_code".to_string(),
            response_types: "code".to_string(),
            created_at: Utc::now(),
            updated_at: Utc::now(),
            is_active: true,
        };
        db.create_oauth_client(&client)
            .expect("Failed to create client");

        let auth_code = DbAuthCode {
            id: 0,
            code: "test_code_123".to_string(),
            client_id: "test_client".to_string(),
            user_id: "test_user".to_string(),
            redirect_uri: "http://localhost:3000/callback".to_string(),
            scope: Some("openid".to_string()),
            expires_at: Utc::now() + chrono::Duration::minutes(10),
            created_at: Utc::now(),
            is_used: false,
            code_challenge: Some("challenge123".to_string()),
            code_challenge_method: Some("S256".to_string()),
        };

        let id = db
            .create_auth_code(&auth_code)
            .expect("Failed to create auth code");
        assert!(id > 0);

        let retrieved = db
            .get_auth_code("test_code_123")
            .expect("Failed to get auth code");
        assert!(retrieved.is_some());
        let code = retrieved.unwrap();
        assert_eq!(code.client_id, "test_client");
        assert_eq!(code.is_used, false);

        db.mark_auth_code_used("test_code_123")
            .expect("Failed to mark code as used");
        let updated = db
            .get_auth_code("test_code_123")
            .expect("Failed to get auth code");
        assert_eq!(updated.unwrap().is_used, true);
    }
}