senax_pgsql_parser/
lib.rs

1//! PostgreSQL Database Schema Parser
2//!
3//! This crate provides functionality to read PostgreSQL database schema information,
4//! provide it as structured data, and generate DDL statements.
5//!
6//! # Main Features
7//!
8//! - Read table structures from PostgreSQL databases
9//! - PostGIS extension support
10//! - DDL generation (CREATE TABLE, DROP TABLE)
11//! - Management of foreign key constraints, indexes, and CHECK constraints
12//! - Accurate handling of Serial types
13//! - Roundtrip testing functionality
14//!
15//! # Usage Example
16//!
17//! ```rust,no_run
18//! use senax_pgsql_parser::{connect_to_database, get_database_schema};
19//!
20//! #[tokio::main]
21//! async fn main() -> Result<(), Box<dyn std::error::Error>> {
22//!     let pool = connect_to_database("postgresql://user:pass@localhost/db").await?;
23//!     let schema = get_database_schema(&pool).await?;
24//!     
25//!     println!("Number of tables: {}", schema.tables.len());
26//!     for table in &schema.tables {
27//!         println!("Table: {}", table.table_name);
28//!         println!("DDL: {}", table.to_ddl());
29//!     }
30//!     
31//!     Ok(())
32//! }
33//! ```
34
35use serde::{Deserialize, Serialize};
36use sqlx::{PgPool, Row};
37use std::collections::HashMap;
38use std::fmt;
39
40/// Parse PostgreSQL array string and convert to Vec<String>
41fn parse_postgres_array(array_str: &str) -> Vec<String> {
42    if array_str.is_empty() || array_str == "{}" {
43        return vec![];
44    }
45
46    // Parse string in "{item1,item2,item3}" format
47    let trimmed = array_str.trim_start_matches('{').trim_end_matches('}');
48    if trimmed.is_empty() {
49        return vec![];
50    }
51
52    trimmed
53        .split(',')
54        .map(|s| s.trim().trim_matches('"').to_string())
55        .collect()
56}
57
58/// Parsed default value types
59#[derive(Debug, Clone, PartialEq, Serialize, Deserialize)]
60pub enum DefaultValue {
61    /// String literal value (unescaped)
62    String(String),
63    /// Integer value
64    Integer(i64),
65    /// Floating point value
66    Float(f64),
67    /// Boolean value
68    Boolean(bool),
69    /// NULL value
70    Null,
71    /// CURRENT_TIMESTAMP
72    CurrentTimestamp,
73    /// CURRENT_DATE
74    CurrentDate,
75    /// CURRENT_TIME
76    CurrentTime,
77    /// Function call or expression (e.g., nextval(...))
78    Expression(String),
79    /// Binary/bytea value
80    Binary(String),
81}
82
83impl fmt::Display for DefaultValue {
84    fn fmt(&self, f: &mut fmt::Formatter<'_>) -> fmt::Result {
85        match self {
86            DefaultValue::String(s) => write!(f, "String: \"{}\"", s),
87            DefaultValue::Integer(i) => write!(f, "Integer: {}", i),
88            DefaultValue::Float(fl) => write!(f, "Float: {}", fl),
89            DefaultValue::Boolean(b) => write!(f, "Boolean: {}", b),
90            DefaultValue::Null => write!(f, "Null"),
91            DefaultValue::CurrentTimestamp => write!(f, "CURRENT_TIMESTAMP"),
92            DefaultValue::CurrentDate => write!(f, "CURRENT_DATE"),
93            DefaultValue::CurrentTime => write!(f, "CURRENT_TIME"),
94            DefaultValue::Expression(e) => write!(f, "Expression: {}", e),
95            DefaultValue::Binary(b) => write!(f, "Binary: {}", b),
96        }
97    }
98}
99
100impl DefaultValue {
101    /// Convert to DDL-compatible string representation
102    pub fn to_ddl_string(&self) -> String {
103        match self {
104            DefaultValue::String(s) => {
105                // Escape single quotes for SQL
106                let escaped = s.replace('\'', "''");
107                format!("'{}'", escaped)
108            }
109            DefaultValue::Integer(i) => i.to_string(),
110            DefaultValue::Float(f) => f.to_string(),
111            DefaultValue::Boolean(b) => b.to_string(),
112            DefaultValue::Null => "NULL".to_string(),
113            DefaultValue::CurrentTimestamp => "CURRENT_TIMESTAMP".to_string(),
114            DefaultValue::CurrentDate => "CURRENT_DATE".to_string(),
115            DefaultValue::CurrentTime => "CURRENT_TIME".to_string(),
116            DefaultValue::Expression(e) => e.clone(),
117            DefaultValue::Binary(b) => format!("'{}'::bytea", b),
118        }
119    }
120}
121
122/// Parse PostgreSQL default value expression
123///
124/// This function parses PostgreSQL default value strings and returns a structured representation.
125///
126/// # Examples
127///
128/// ```
129/// use senax_pgsql_parser::{parse_default_value, DefaultValue};
130///
131/// // String with escaped quotes
132/// let result = parse_default_value("'it''s a test'::character varying");
133/// assert_eq!(result, DefaultValue::String("it's a test".to_string()));
134///
135/// // Simple string
136/// let result = parse_default_value("'simple'::text");
137/// assert_eq!(result, DefaultValue::String("simple".to_string()));
138///
139/// // Integer
140/// let result = parse_default_value("42");
141/// assert_eq!(result, DefaultValue::Integer(42));
142///
143/// // Float
144/// let result = parse_default_value("99.99");
145/// assert_eq!(result, DefaultValue::Float(99.99));
146///
147/// // Boolean
148/// let result = parse_default_value("true");
149/// assert_eq!(result, DefaultValue::Boolean(true));
150///
151/// // NULL
152/// let result = parse_default_value("NULL");
153/// assert_eq!(result, DefaultValue::Null);
154///
155/// // Current timestamp
156/// let result = parse_default_value("CURRENT_TIMESTAMP");
157/// assert_eq!(result, DefaultValue::CurrentTimestamp);
158///
159/// // Current date
160/// let result = parse_default_value("CURRENT_DATE");
161/// assert_eq!(result, DefaultValue::CurrentDate);
162///
163/// // Sequence
164/// let result = parse_default_value("nextval('test_seq'::regclass)");
165/// assert_eq!(result, DefaultValue::Expression("nextval('test_seq'::regclass)".to_string()));
166/// ```
167pub fn parse_default_value(default_str: &str) -> DefaultValue {
168    let trimmed = default_str.trim();
169
170    // Check for NULL
171    if trimmed.eq_ignore_ascii_case("NULL") {
172        return DefaultValue::Null;
173    }
174
175    // Check for boolean values
176    if trimmed.eq_ignore_ascii_case("true") {
177        return DefaultValue::Boolean(true);
178    }
179    if trimmed.eq_ignore_ascii_case("false") {
180        return DefaultValue::Boolean(false);
181    }
182
183    // Check for CURRENT_* functions
184    if trimmed.eq_ignore_ascii_case("CURRENT_TIMESTAMP") {
185        return DefaultValue::CurrentTimestamp;
186    }
187    if trimmed.eq_ignore_ascii_case("CURRENT_DATE") {
188        return DefaultValue::CurrentDate;
189    }
190    if trimmed.eq_ignore_ascii_case("CURRENT_TIME") {
191        return DefaultValue::CurrentTime;
192    }
193
194    // Check for string literals (starts with single quote)
195    if trimmed.starts_with('\'') {
196        return parse_string_literal(trimmed);
197    }
198
199    // Check for numeric values
200    if let Ok(int_val) = trimmed.parse::<i64>() {
201        return DefaultValue::Integer(int_val);
202    }
203    if let Ok(float_val) = trimmed.parse::<f64>() {
204        return DefaultValue::Float(float_val);
205    }
206
207    // Everything else is treated as an expression (functions, etc.)
208    DefaultValue::Expression(trimmed.to_string())
209}
210
211/// Parse PostgreSQL string literal with type cast
212///
213/// Handles formats like:
214/// - 'simple'::text
215/// - 'it''s a test'::character varying
216/// - '\x00'::bytea
217fn parse_string_literal(input: &str) -> DefaultValue {
218    let input = input.trim();
219
220    // Find the closing quote
221    let mut chars = input.chars().peekable();
222    let mut result = String::new();
223    let mut type_cast = String::new();
224    let mut after_string = false;
225
226    // Skip the opening quote
227    if chars.next() != Some('\'') {
228        return DefaultValue::Expression(input.to_string());
229    }
230    let mut in_string = true;
231
232    while let Some(ch) = chars.next() {
233        if in_string {
234            if ch == '\'' {
235                // Check if it's an escaped quote
236                if chars.peek() == Some(&'\'') {
237                    // Escaped quote: '' -> '
238                    result.push('\'');
239                    chars.next(); // consume the second quote
240                } else {
241                    // End of string
242                    in_string = false;
243                    after_string = true;
244                }
245            } else {
246                result.push(ch);
247            }
248        } else if after_string {
249            // Collect the rest (type cast)
250            type_cast.push(ch);
251        }
252    }
253
254    // Check if it's a bytea type
255    if type_cast.contains("bytea") {
256        return DefaultValue::Binary(result);
257    }
258
259    // Return as string
260    DefaultValue::String(result)
261}
262
263/// PostGIS geometry types
264#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
265pub enum GeometryType {
266    Point,
267    LineString,
268    Polygon,
269    MultiPoint,
270    MultiLineString,
271    MultiPolygon,
272    GeometryCollection,
273}
274
275impl fmt::Display for GeometryType {
276    fn fmt(&self, f: &mut fmt::Formatter<'_>) -> fmt::Result {
277        let s = match self {
278            GeometryType::Point => "POINT",
279            GeometryType::LineString => "LINESTRING",
280            GeometryType::Polygon => "POLYGON",
281            GeometryType::MultiPoint => "MULTIPOINT",
282            GeometryType::MultiLineString => "MULTILINESTRING",
283            GeometryType::MultiPolygon => "MULTIPOLYGON",
284            GeometryType::GeometryCollection => "GEOMETRYCOLLECTION",
285        };
286        write!(f, "{}", s)
287    }
288}
289
290/// PostGIS geometry detailed information
291#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
292pub struct GeometryInfo {
293    pub geometry_type: GeometryType,
294    pub srid: Option<i32>,
295    pub dimension: Option<i32>,
296}
297
298impl fmt::Display for GeometryInfo {
299    fn fmt(&self, f: &mut fmt::Formatter<'_>) -> fmt::Result {
300        match (&self.srid, &self.dimension) {
301            (Some(srid), Some(_dim)) => write!(f, "({}, {})", self.geometry_type, srid),
302            (Some(srid), None) => write!(f, "({}, {})", self.geometry_type, srid),
303            (None, Some(_dim)) => write!(f, "({})", self.geometry_type),
304            (None, None) => write!(f, "({})", self.geometry_type),
305        }
306    }
307}
308
309/// PostgreSQL data types
310#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
311pub enum PostgreSQLDataType {
312    // Integer types
313    SmallInt,
314    Integer,
315    BigInt,
316
317    // Serial types
318    SmallSerial,
319    Serial,
320    BigSerial,
321
322    // Floating point types
323    Real,
324    DoublePrecision,
325
326    // Numeric types
327    Numeric(Option<i32>, Option<i32>), // precision, scale
328    Decimal(Option<i32>, Option<i32>), // precision, scale
329
330    // String types
331    Char(Option<i32>),
332    Varchar(Option<i32>),
333    Text,
334
335    // Binary type
336    Bytea,
337
338    // Date/time types
339    Date,
340    Time,
341    TimeWithTimeZone,
342    Timestamp,
343    TimestampWithTimeZone,
344    Interval,
345
346    // Boolean type
347    Boolean,
348
349    // UUID type
350    Uuid,
351
352    // JSON types
353    Json,
354    Jsonb,
355
356    // Array type
357    Array(Box<PostgreSQLDataType>),
358
359    // PostGIS types
360    Geometry(Option<GeometryInfo>),
361    Geography(Option<GeometryInfo>),
362
363    // Custom types (ENUM, etc.)
364    Custom(String),
365
366    // Others
367    Unknown(String),
368}
369
370impl fmt::Display for PostgreSQLDataType {
371    fn fmt(&self, f: &mut fmt::Formatter<'_>) -> fmt::Result {
372        match self {
373            PostgreSQLDataType::SmallInt => write!(f, "smallint"),
374            PostgreSQLDataType::Integer => write!(f, "integer"),
375            PostgreSQLDataType::BigInt => write!(f, "bigint"),
376            PostgreSQLDataType::SmallSerial => write!(f, "smallserial"),
377            PostgreSQLDataType::Serial => write!(f, "serial"),
378            PostgreSQLDataType::BigSerial => write!(f, "bigserial"),
379            PostgreSQLDataType::Real => write!(f, "real"),
380            PostgreSQLDataType::DoublePrecision => write!(f, "double precision"),
381            PostgreSQLDataType::Numeric(p, s) => match (p, s) {
382                (Some(precision), Some(scale)) => write!(f, "numeric({},{})", precision, scale),
383                (Some(precision), None) => write!(f, "numeric({})", precision),
384                _ => write!(f, "numeric"),
385            },
386            PostgreSQLDataType::Decimal(p, s) => match (p, s) {
387                (Some(precision), Some(scale)) => write!(f, "numeric({},{})", precision, scale),
388                (Some(precision), None) => write!(f, "numeric({})", precision),
389                _ => write!(f, "numeric"),
390            },
391            PostgreSQLDataType::Char(len) => match len {
392                Some(l) => write!(f, "char({})", l),
393                None => write!(f, "char"),
394            },
395            PostgreSQLDataType::Varchar(len) => match len {
396                Some(l) => write!(f, "varchar({})", l),
397                None => write!(f, "varchar"),
398            },
399            PostgreSQLDataType::Text => write!(f, "text"),
400            PostgreSQLDataType::Bytea => write!(f, "bytea"),
401            PostgreSQLDataType::Date => write!(f, "date"),
402            PostgreSQLDataType::Time => write!(f, "time"),
403            PostgreSQLDataType::TimeWithTimeZone => write!(f, "time with time zone"),
404            PostgreSQLDataType::Timestamp => write!(f, "timestamp"),
405            PostgreSQLDataType::TimestampWithTimeZone => write!(f, "timestamp with time zone"),
406            PostgreSQLDataType::Interval => write!(f, "interval"),
407            PostgreSQLDataType::Boolean => write!(f, "boolean"),
408            PostgreSQLDataType::Uuid => write!(f, "uuid"),
409            PostgreSQLDataType::Json => write!(f, "json"),
410            PostgreSQLDataType::Jsonb => write!(f, "jsonb"),
411            PostgreSQLDataType::Array(inner) => write!(f, "{}[]", inner),
412            PostgreSQLDataType::Geometry(info) => match info {
413                Some(geo_info) => write!(f, "geometry{}", geo_info),
414                None => write!(f, "geometry"),
415            },
416            PostgreSQLDataType::Geography(info) => match info {
417                Some(geo_info) => write!(f, "geography{}", geo_info),
418                None => write!(f, "geography"),
419            },
420            PostgreSQLDataType::Custom(type_name) => write!(f, "{}", type_name),
421            PostgreSQLDataType::Unknown(type_name) => write!(f, "{}", type_name),
422        }
423    }
424}
425
426impl PostgreSQLDataType {
427    /// Get string representation for DDL
428    pub fn to_ddl_string(&self) -> String {
429        match self {
430            PostgreSQLDataType::Array(inner) => match inner.as_ref() {
431                PostgreSQLDataType::Geometry(Some(info)) => {
432                    format!("geometry{}[]", info)
433                }
434                PostgreSQLDataType::Geography(Some(info)) => {
435                    format!("geography{}[]", info)
436                }
437                _ => format!("{}[]", inner.to_ddl_string()),
438            },
439            _ => self.to_string(),
440        }
441    }
442}
443
444/// Column information
445#[derive(Debug, Clone, Serialize, Deserialize, PartialEq)]
446pub struct ColumnInfo {
447    pub column_name: String,
448    pub data_type: PostgreSQLDataType,
449    pub is_nullable: bool,
450    pub column_default: Option<DefaultValue>,
451    pub character_maximum_length: Option<i32>,
452    pub numeric_precision: Option<i32>,
453    pub numeric_scale: Option<i32>,
454    pub is_primary_key: bool,
455    pub comment: Option<String>,
456    pub collate: Option<String>,
457}
458
459impl ColumnInfo {
460    /// Generate DDL definition for column
461    pub fn to_ddl(&self) -> String {
462        let mut ddl = format!(
463            "{} {}",
464            escape_db_identifier(&self.column_name),
465            self.data_type.to_ddl_string()
466        );
467
468        // Add COLLATE clause for string types
469        if let Some(collate) = &self.collate {
470            match &self.data_type {
471                PostgreSQLDataType::Char(_)
472                | PostgreSQLDataType::Varchar(_)
473                | PostgreSQLDataType::Text => {
474                    ddl.push_str(&format!(" COLLATE \"{}\"", collate));
475                }
476                _ => {}
477            }
478        }
479
480        if !self.is_nullable {
481            ddl.push_str(" NOT NULL");
482        }
483
484        // Omit DEFAULT clause for Serial types (auto-generated)
485        if let Some(default) = &self.column_default {
486            match &self.data_type {
487                PostgreSQLDataType::SmallSerial
488                | PostgreSQLDataType::Serial
489                | PostgreSQLDataType::BigSerial => {
490                    // For Serial types, DEFAULT clause is automatically added, so omit it
491                }
492                _ => {
493                    ddl.push_str(&format!(" DEFAULT {}", default.to_ddl_string()));
494                }
495            }
496        }
497
498        ddl
499    }
500}
501
502/// Foreign key constraint actions
503#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
504pub enum ForeignKeyAction {
505    NoAction,
506    Restrict,
507    Cascade,
508    SetNull,
509    SetDefault,
510}
511
512impl ForeignKeyAction {
513    /// Convert string to ForeignKeyAction
514    pub fn from_str(s: &str) -> Option<Self> {
515        match s.to_uppercase().as_str() {
516            "NO ACTION" => Some(ForeignKeyAction::NoAction),
517            "RESTRICT" => Some(ForeignKeyAction::Restrict),
518            "CASCADE" => Some(ForeignKeyAction::Cascade),
519            "SET NULL" => Some(ForeignKeyAction::SetNull),
520            "SET DEFAULT" => Some(ForeignKeyAction::SetDefault),
521            _ => None,
522        }
523    }
524
525    /// Convert ForeignKeyAction to string
526    pub fn to_string(&self) -> String {
527        match self {
528            ForeignKeyAction::NoAction => "NO ACTION".to_string(),
529            ForeignKeyAction::Restrict => "RESTRICT".to_string(),
530            ForeignKeyAction::Cascade => "CASCADE".to_string(),
531            ForeignKeyAction::SetNull => "SET NULL".to_string(),
532            ForeignKeyAction::SetDefault => "SET DEFAULT".to_string(),
533        }
534    }
535}
536
537impl fmt::Display for ForeignKeyAction {
538    fn fmt(&self, f: &mut fmt::Formatter<'_>) -> fmt::Result {
539        write!(f, "{}", self.to_string())
540    }
541}
542
543/// Index types
544#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
545pub enum IndexType {
546    BTree,
547    Hash,
548    Gin,
549    Gist,
550    SpGist,
551    Brin,
552    Bloom,
553}
554
555impl IndexType {
556    /// Convert string to IndexType
557    pub fn from_str(s: &str) -> Option<Self> {
558        match s.to_lowercase().as_str() {
559            "btree" => Some(IndexType::BTree),
560            "hash" => Some(IndexType::Hash),
561            "gin" => Some(IndexType::Gin),
562            "gist" => Some(IndexType::Gist),
563            "spgist" => Some(IndexType::SpGist),
564            "brin" => Some(IndexType::Brin),
565            "bloom" => Some(IndexType::Bloom),
566            _ => None,
567        }
568    }
569
570    /// Convert IndexType to string
571    pub fn to_string(&self) -> String {
572        match self {
573            IndexType::BTree => "btree".to_string(),
574            IndexType::Hash => "hash".to_string(),
575            IndexType::Gin => "gin".to_string(),
576            IndexType::Gist => "gist".to_string(),
577            IndexType::SpGist => "spgist".to_string(),
578            IndexType::Brin => "brin".to_string(),
579            IndexType::Bloom => "bloom".to_string(),
580        }
581    }
582}
583
584impl fmt::Display for IndexType {
585    fn fmt(&self, f: &mut fmt::Formatter<'_>) -> fmt::Result {
586        write!(f, "{}", self.to_string())
587    }
588}
589
590/// Foreign key constraint information
591#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
592pub struct ForeignKeyConstraint {
593    pub constraint_name: String,
594    pub columns: Vec<String>,
595    pub referenced_table: String,
596    pub referenced_columns: Vec<String>,
597    pub on_delete: Option<ForeignKeyAction>,
598    pub on_update: Option<ForeignKeyAction>,
599    pub is_deferrable: bool,
600    pub initially_deferred: bool,
601}
602
603impl ForeignKeyConstraint {
604    /// Generate DDL for foreign key constraint
605    pub fn to_ddl(&self) -> String {
606        let delete_action = match &self.on_delete {
607            Some(action) => format!(" ON DELETE {}", action),
608            None => String::new(),
609        };
610        let update_action = match &self.on_update {
611            Some(action) => format!(" ON UPDATE {}", action),
612            None => String::new(),
613        };
614        let deferrable = if self.is_deferrable {
615            if self.initially_deferred {
616                " DEFERRABLE INITIALLY DEFERRED"
617            } else {
618                " DEFERRABLE INITIALLY IMMEDIATE"
619            }
620        } else {
621            ""
622        };
623
624        format!(
625            "CONSTRAINT {} FOREIGN KEY ({}) REFERENCES {} ({}){}{}{}",
626            escape_db_identifier(&self.constraint_name),
627            self.columns
628                .iter()
629                .map(|v| escape_db_identifier(v))
630                .collect::<Vec<_>>()
631                .join(", "),
632            escape_db_identifier(&self.referenced_table),
633            self.referenced_columns
634                .iter()
635                .map(|v| escape_db_identifier(v))
636                .collect::<Vec<_>>()
637                .join(", "),
638            delete_action,
639            update_action,
640            deferrable
641        )
642    }
643}
644
645/// Index information
646#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
647pub struct IndexInfo {
648    pub index_name: String,
649    pub columns: Vec<String>,
650    pub is_unique: bool,
651    pub is_primary: bool,
652    pub index_type: IndexType,
653    pub condition: Option<String>, // partial index condition
654}
655
656impl IndexInfo {
657    /// Generate DDL for index creation
658    pub fn to_ddl(&self, table_schema: &str, table_name: &str) -> String {
659        let unique_clause = if self.is_unique { "UNIQUE " } else { "" };
660        let using_clause = if self.index_type != IndexType::BTree {
661            format!(" USING {}", self.index_type.to_string().to_uppercase())
662        } else {
663            String::new()
664        };
665        let where_clause = match &self.condition {
666            Some(condition) => format!(" WHERE {}", condition),
667            None => String::new(),
668        };
669
670        format!(
671            "CREATE {}INDEX {} ON {}.{}{} ({}){}",
672            unique_clause,
673            escape_db_identifier(&self.index_name),
674            escape_db_identifier(&table_schema),
675            escape_db_identifier(&table_name),
676            using_clause,
677            self.columns
678                .iter()
679                .map(|v| escape_db_identifier(v))
680                .collect::<Vec<_>>()
681                .join(", "),
682            where_clause
683        )
684    }
685}
686
687/// CHECK constraint information
688#[derive(Debug, Clone, Serialize, Deserialize, PartialEq, Eq)]
689pub struct CheckConstraint {
690    pub constraint_name: String,
691    pub check_clause: String,
692}
693
694impl CheckConstraint {
695    /// Generate DDL for CHECK constraint
696    pub fn to_ddl(&self) -> String {
697        format!(
698            "CONSTRAINT {} CHECK ({})",
699            escape_db_identifier(&self.constraint_name),
700            self.check_clause
701        )
702    }
703}
704
705/// Table information
706#[derive(Debug, Clone, Serialize, Deserialize, PartialEq)]
707pub struct TableInfo {
708    pub table_schema: String,
709    pub table_name: String,
710    pub columns: Vec<ColumnInfo>,
711    pub foreign_keys: Vec<ForeignKeyConstraint>,
712    pub indexes: Vec<IndexInfo>,
713    pub check_constraints: Vec<CheckConstraint>,
714    pub comment: Option<String>,
715}
716
717impl TableInfo {
718    /// Check if table uses PostGIS extension
719    pub fn uses_postgis(&self) -> bool {
720        self.columns.iter().any(|col| match &col.data_type {
721            PostgreSQLDataType::Geometry(_) | PostgreSQLDataType::Geography(_) => true,
722            PostgreSQLDataType::Array(inner) => matches!(
723                inner.as_ref(),
724                PostgreSQLDataType::Geometry(_) | PostgreSQLDataType::Geography(_)
725            ),
726            _ => false,
727        })
728    }
729
730    /// Get details of columns using PostGIS types
731    pub fn get_postgis_types(&self) -> HashMap<String, i32> {
732        let mut postgis_types = HashMap::new();
733
734        for col in &self.columns {
735            match &col.data_type {
736                PostgreSQLDataType::Geometry(_) => {
737                    *postgis_types.entry("geometry".to_string()).or_insert(0) += 1;
738                }
739                PostgreSQLDataType::Geography(_) => {
740                    *postgis_types.entry("geography".to_string()).or_insert(0) += 1;
741                }
742                PostgreSQLDataType::Array(inner) => match inner.as_ref() {
743                    PostgreSQLDataType::Geometry(_) => {
744                        *postgis_types.entry("geometry[]".to_string()).or_insert(0) += 1;
745                    }
746                    PostgreSQLDataType::Geography(_) => {
747                        *postgis_types.entry("geography[]".to_string()).or_insert(0) += 1;
748                    }
749                    _ => {}
750                },
751                _ => {}
752            }
753        }
754
755        postgis_types
756    }
757
758    /// Generate CREATE TABLE DDL
759    pub fn to_ddl(&self) -> String {
760        let mut ddl = format!(
761            "CREATE TABLE {}.{} (\n",
762            escape_db_identifier(&self.table_schema),
763            escape_db_identifier(&self.table_name)
764        );
765
766        // Column definitions
767        let column_definitions: Vec<String> = self
768            .columns
769            .iter()
770            .map(|col| format!("  {}", col.to_ddl()))
771            .collect();
772
773        let mut constraints = Vec::new();
774
775        // PRIMARY KEY constraints
776        let primary_key_columns: Vec<&str> = self
777            .columns
778            .iter()
779            .filter(|col| col.is_primary_key)
780            .map(|col| col.column_name.as_str())
781            .collect();
782
783        if !primary_key_columns.is_empty() {
784            constraints.push(format!(
785                "  CONSTRAINT pk_{} PRIMARY KEY ({})",
786                self.table_name,
787                primary_key_columns
788                    .iter()
789                    .map(|v| escape_db_identifier(v))
790                    .collect::<Vec<_>>()
791                    .join(", ")
792            ));
793        }
794
795        // FOREIGN KEY constraints
796        for fk in &self.foreign_keys {
797            let delete_action = match &fk.on_delete {
798                Some(action) => format!(" ON DELETE {}", action),
799                None => String::new(),
800            };
801            let update_action = match &fk.on_update {
802                Some(action) => format!(" ON UPDATE {}", action),
803                None => String::new(),
804            };
805            let deferrable = if fk.is_deferrable {
806                if fk.initially_deferred {
807                    " DEFERRABLE INITIALLY DEFERRED"
808                } else {
809                    " DEFERRABLE INITIALLY IMMEDIATE"
810                }
811            } else {
812                ""
813            };
814
815            constraints.push(format!(
816                "  CONSTRAINT {} FOREIGN KEY ({}) REFERENCES {} ({}){}{}{}",
817                escape_db_identifier(&fk.constraint_name),
818                fk.columns
819                    .iter()
820                    .map(|v| escape_db_identifier(v))
821                    .collect::<Vec<_>>()
822                    .join(", "),
823                escape_db_identifier(&fk.referenced_table),
824                fk.referenced_columns
825                    .iter()
826                    .map(|v| escape_db_identifier(v))
827                    .collect::<Vec<_>>()
828                    .join(", "),
829                delete_action,
830                update_action,
831                deferrable
832            ));
833        }
834
835        // CHECK constraints
836        for check in &self.check_constraints {
837            constraints.push(format!(
838                "  CONSTRAINT {} CHECK ({})",
839                escape_db_identifier(&check.constraint_name),
840                check.check_clause
841            ));
842        }
843
844        // Combine all definitions
845        let mut all_definitions = column_definitions;
846        all_definitions.extend(constraints);
847
848        ddl.push_str(&all_definitions.join(",\n"));
849        ddl.push_str("\n);");
850
851        ddl
852    }
853
854    /// Generate DDL for index creation
855    pub fn to_index_ddl(&self) -> Vec<String> {
856        self.indexes
857            .iter()
858            .filter(|idx| !idx.is_primary) // Exclude PRIMARY KEY indexes
859            .map(|idx| idx.to_ddl(&self.table_schema, &self.table_name))
860            .collect()
861    }
862
863    /// Generate DDL for table and column comments
864    pub fn to_comment_ddl(&self) -> Vec<String> {
865        let mut comments = Vec::new();
866
867        // Add table comment if exists
868        if let Some(table_comment) = &self.comment {
869            comments.push(format!(
870                "COMMENT ON TABLE {}.{} IS '{}'",
871                escape_db_identifier(&self.table_schema),
872                escape_db_identifier(&self.table_name),
873                table_comment.replace("'", "''") // Escape single quotes
874            ));
875        }
876
877        // Add column comments
878        for col in &self.columns {
879            if let Some(comment) = &col.comment {
880                comments.push(format!(
881                    "COMMENT ON COLUMN {}.{}.{} IS '{}'",
882                    escape_db_identifier(&self.table_schema),
883                    escape_db_identifier(&self.table_name),
884                    escape_db_identifier(&col.column_name),
885                    comment.replace("'", "''") // Escape single quotes
886                ));
887            }
888        }
889
890        comments
891    }
892
893    /// Get list of referenced tables
894    pub fn get_referenced_tables(&self) -> Vec<String> {
895        self.foreign_keys
896            .iter()
897            .map(|fk| fk.referenced_table.clone())
898            .collect()
899    }
900
901    /// Check if table has foreign keys
902    pub fn has_foreign_keys(&self) -> bool {
903        !self.foreign_keys.is_empty()
904    }
905}
906
907/// Complete database schema information
908#[derive(Debug, Clone, Serialize, Deserialize, PartialEq)]
909pub struct DatabaseSchema {
910    pub tables: Vec<TableInfo>,
911}
912
913impl DatabaseSchema {
914    /// Check if PostGIS extension is required
915    pub fn requires_postgis(&self) -> bool {
916        self.tables.iter().any(|table| table.uses_postgis())
917    }
918
919    /// Get list of PostGIS tables
920    pub fn get_postgis_tables(&self) -> Vec<&TableInfo> {
921        self.tables
922            .iter()
923            .filter(|table| table.uses_postgis())
924            .collect()
925    }
926
927    /// Get usage statistics for all PostGIS types
928    pub fn get_all_postgis_types(&self) -> HashMap<String, i32> {
929        let mut all_types = HashMap::new();
930
931        for table in &self.tables {
932            let table_types = table.get_postgis_types();
933            for (type_name, count) in table_types {
934                *all_types.entry(type_name).or_insert(0) += count;
935            }
936        }
937
938        all_types
939    }
940
941    /// Generate CREATE DDL (considering dependencies)
942    pub fn to_create_ddl(&self) -> String {
943        let mut ddl_parts = Vec::new();
944
945        // If PostGIS extension is required
946        if self.requires_postgis() {
947            ddl_parts.push("CREATE EXTENSION IF NOT EXISTS postgis;".to_string());
948            ddl_parts.push("".to_string()); // Empty line
949        }
950
951        // Create tables without foreign keys first
952        let mut created_tables = std::collections::HashSet::new();
953        let mut remaining_tables: Vec<&TableInfo> = self.tables.iter().collect();
954
955        // Create from tables without foreign keys
956        while !remaining_tables.is_empty() {
957            let mut progress = false;
958
959            remaining_tables.retain(|table| {
960                let can_create = !table.has_foreign_keys()
961                    || table.get_referenced_tables().iter().all(|ref_table| {
962                        created_tables.contains(ref_table) || ref_table == &table.table_name
963                    });
964
965                if can_create {
966                    ddl_parts.push(table.to_ddl());
967                    ddl_parts.push("".to_string()); // Empty line
968
969                    // Add table and column comments
970                    let comment_ddls = table.to_comment_ddl();
971                    for comment_ddl in comment_ddls {
972                        ddl_parts.push(comment_ddl);
973                    }
974                    if !table.to_comment_ddl().is_empty() {
975                        ddl_parts.push("".to_string()); // Empty line after comments
976                    }
977
978                    // Add indexes
979                    let index_ddls = table.to_index_ddl();
980                    for index_ddl in index_ddls {
981                        ddl_parts.push(index_ddl);
982                    }
983                    if !table.to_index_ddl().is_empty() {
984                        ddl_parts.push("".to_string()); // Empty line after indexes
985                    }
986
987                    created_tables.insert(table.table_name.clone());
988                    progress = true;
989                    false // Remove this table from remaining_tables
990                } else {
991                    true // Keep this table in remaining_tables
992                }
993            });
994
995            // If no progress (circular references, etc.), force create remaining tables
996            if !progress && !remaining_tables.is_empty() {
997                let table = remaining_tables.remove(0);
998                ddl_parts.push(table.to_ddl());
999                ddl_parts.push("".to_string());
1000
1001                // Add table and column comments
1002                let comment_ddls = table.to_comment_ddl();
1003                for comment_ddl in comment_ddls {
1004                    ddl_parts.push(comment_ddl);
1005                }
1006                if !table.to_comment_ddl().is_empty() {
1007                    ddl_parts.push("".to_string()); // Empty line after comments
1008                }
1009
1010                // Add indexes
1011                let index_ddls = table.to_index_ddl();
1012                for index_ddl in index_ddls {
1013                    ddl_parts.push(index_ddl);
1014                }
1015                if !table.to_index_ddl().is_empty() {
1016                    ddl_parts.push("".to_string()); // Empty line after indexes
1017                }
1018
1019                created_tables.insert(table.table_name.clone());
1020            }
1021        }
1022
1023        ddl_parts.join("\n")
1024    }
1025
1026    /// Generate DROP DDL (reverse order of CREATE DDL)
1027    pub fn to_drop_ddl(&self) -> String {
1028        let mut ddl_parts = Vec::new();
1029
1030        // Drop tables with foreign keys first
1031        let mut dropped_tables = std::collections::HashSet::new();
1032        let mut remaining_tables: Vec<&TableInfo> = self.tables.iter().collect();
1033
1034        while !remaining_tables.is_empty() {
1035            let mut progress = false;
1036
1037            remaining_tables.retain(|table| {
1038                let can_drop = self.tables.iter().all(|other_table| {
1039                    other_table.table_name == table.table_name
1040                        || dropped_tables.contains(&other_table.table_name)
1041                        || !other_table
1042                            .get_referenced_tables()
1043                            .contains(&table.table_name)
1044                });
1045
1046                if can_drop {
1047                    ddl_parts.push(format!(
1048                        "DROP TABLE IF EXISTS {}.{} CASCADE;",
1049                        escape_db_identifier(&table.table_schema),
1050                        escape_db_identifier(&table.table_name)
1051                    ));
1052                    dropped_tables.insert(table.table_name.clone());
1053                    progress = true;
1054                    false
1055                } else {
1056                    true
1057                }
1058            });
1059
1060            if !progress && !remaining_tables.is_empty() {
1061                let table = remaining_tables.remove(0);
1062                ddl_parts.push(format!(
1063                    "DROP TABLE IF EXISTS {}.{} CASCADE;",
1064                    escape_db_identifier(&table.table_schema),
1065                    escape_db_identifier(&table.table_name)
1066                ));
1067                dropped_tables.insert(table.table_name.clone());
1068            }
1069        }
1070
1071        ddl_parts.join("\n")
1072    }
1073}
1074
1075/// Connect to database
1076pub async fn connect_to_database(database_url: &str) -> Result<PgPool, sqlx::Error> {
1077    PgPool::connect(database_url).await
1078}
1079
1080/// Get current schema name
1081pub async fn get_current_schema(pool: &PgPool) -> Result<String, sqlx::Error> {
1082    let row = sqlx::query("SELECT current_schema()")
1083        .fetch_one(pool)
1084        .await?;
1085    Ok(row.get(0))
1086}
1087
1088/// Get complete database schema
1089pub async fn get_database_schema(pool: &PgPool) -> Result<DatabaseSchema, sqlx::Error> {
1090    let current_schema = get_current_schema(pool).await?;
1091    let table_names = get_table_names(pool, &current_schema).await?;
1092
1093    let mut tables = Vec::new();
1094    for table_name in table_names {
1095        let columns = get_table_columns(pool, &current_schema, &table_name).await?;
1096        let foreign_keys = get_foreign_key_constraints(pool, &current_schema, &table_name).await?;
1097        let indexes = get_table_indexes(pool, &current_schema, &table_name).await?;
1098        let check_constraints = get_check_constraints(pool, &current_schema, &table_name).await?;
1099        let table_comment = get_table_comment(pool, &current_schema, &table_name).await?;
1100
1101        tables.push(TableInfo {
1102            table_schema: current_schema.clone(),
1103            table_name,
1104            columns,
1105            foreign_keys,
1106            indexes,
1107            check_constraints,
1108            comment: table_comment,
1109        });
1110    }
1111
1112    Ok(DatabaseSchema { tables })
1113}
1114
1115// Private implementation functions below
1116
1117pub async fn get_table_names(pool: &PgPool, schema: &str) -> Result<Vec<String>, sqlx::Error> {
1118    let rows = sqlx::query(
1119        "SELECT table_name FROM information_schema.tables WHERE table_schema = $1 AND table_type = 'BASE TABLE' ORDER BY table_name"
1120    )
1121    .bind(schema)
1122    .fetch_all(pool)
1123    .await?;
1124
1125    Ok(rows.into_iter().map(|row| row.get(0)).collect())
1126}
1127
1128pub async fn get_table_columns(
1129    pool: &PgPool,
1130    schema: &str,
1131    table: &str,
1132) -> Result<Vec<ColumnInfo>, sqlx::Error> {
1133    let query = r#"
1134        SELECT 
1135            c.column_name,
1136            c.data_type,
1137            c.is_nullable,
1138            c.column_default,
1139            c.character_maximum_length,
1140            c.numeric_precision,
1141            c.numeric_scale,
1142            c.udt_name,
1143            COALESCE(pk.is_primary, false) as is_primary_key,
1144            pgd.description as comment,
1145            c.collation_name
1146        FROM information_schema.columns c
1147        LEFT JOIN (
1148            SELECT 
1149                kcu.column_name,
1150                true as is_primary
1151            FROM information_schema.table_constraints tc
1152            JOIN information_schema.key_column_usage kcu 
1153                ON tc.constraint_name = kcu.constraint_name
1154                AND tc.table_schema = kcu.table_schema
1155            WHERE tc.constraint_type = 'PRIMARY KEY'
1156                AND tc.table_schema = $1
1157                AND tc.table_name = $2
1158        ) pk ON c.column_name = pk.column_name
1159        LEFT JOIN pg_class pgc ON pgc.relname = c.table_name AND pgc.relnamespace = (
1160            SELECT oid FROM pg_namespace WHERE nspname = c.table_schema
1161        )
1162        LEFT JOIN pg_attribute pga ON pga.attrelid = pgc.oid AND pga.attname = c.column_name
1163        LEFT JOIN pg_description pgd ON pgd.objoid = pgc.oid AND pgd.objsubid = pga.attnum
1164        WHERE c.table_schema = $1 AND c.table_name = $2
1165        ORDER BY c.ordinal_position
1166    "#;
1167
1168    let rows = sqlx::query(query)
1169        .bind(schema)
1170        .bind(table)
1171        .fetch_all(pool)
1172        .await?;
1173
1174    let mut columns = Vec::new();
1175    for row in rows {
1176        let column_name: String = row.get("column_name");
1177        let data_type_str: String = row.get("data_type");
1178        let udt_name: String = row.get("udt_name");
1179        let is_nullable_str: String = row.get("is_nullable");
1180        let is_nullable = is_nullable_str == "YES";
1181        let column_default_str: Option<String> = row.get("column_default");
1182        let character_maximum_length: Option<i32> = row.get("character_maximum_length");
1183        let numeric_precision: Option<i32> = row.get("numeric_precision");
1184        let numeric_scale: Option<i32> = row.get("numeric_scale");
1185        let is_primary_key: bool = row.get("is_primary_key");
1186        let comment: Option<String> = row.get("comment");
1187        let collation_name: Option<String> = row.get("collation_name");
1188
1189        // Parse default value
1190        let column_default = column_default_str.as_ref().map(|s| parse_default_value(s));
1191
1192        let data_type = parse_data_type(
1193            &data_type_str,
1194            &udt_name,
1195            character_maximum_length,
1196            numeric_precision,
1197            numeric_scale,
1198            &column_default_str,
1199            &column_name,
1200            table,
1201            pool,
1202            schema,
1203        )
1204        .await;
1205
1206        columns.push(ColumnInfo {
1207            column_name,
1208            data_type,
1209            is_nullable,
1210            column_default,
1211            character_maximum_length,
1212            numeric_precision,
1213            numeric_scale,
1214            is_primary_key,
1215            comment,
1216            collate: collation_name,
1217        });
1218    }
1219
1220    Ok(columns)
1221}
1222
1223async fn parse_data_type(
1224    data_type_str: &str,
1225    udt_name: &str,
1226    character_maximum_length: Option<i32>,
1227    numeric_precision: Option<i32>,
1228    numeric_scale: Option<i32>,
1229    column_default: &Option<String>,
1230    column_name: &str,
1231    table_name: &str,
1232    pool: &PgPool,
1233    schema: &str,
1234) -> PostgreSQLDataType {
1235    // Check if this is a Serial type by examining the DEFAULT value
1236    let is_serial = if let Some(default_value) = column_default {
1237        default_value.contains("nextval")
1238            && (default_value.contains(&format!("{}_seq", column_name))
1239                || default_value.contains(&format!("{}_{}_seq", table_name, column_name)))
1240    } else {
1241        false
1242    };
1243
1244    match data_type_str {
1245        "smallint" => {
1246            if is_serial {
1247                PostgreSQLDataType::SmallSerial
1248            } else {
1249                PostgreSQLDataType::SmallInt
1250            }
1251        }
1252        "integer" => {
1253            if is_serial {
1254                PostgreSQLDataType::Serial
1255            } else {
1256                PostgreSQLDataType::Integer
1257            }
1258        }
1259        "bigint" => {
1260            if is_serial {
1261                PostgreSQLDataType::BigSerial
1262            } else {
1263                PostgreSQLDataType::BigInt
1264            }
1265        }
1266        "real" => PostgreSQLDataType::Real,
1267        "double precision" => PostgreSQLDataType::DoublePrecision,
1268        "numeric" => PostgreSQLDataType::Numeric(numeric_precision, numeric_scale),
1269        "character varying" => PostgreSQLDataType::Varchar(character_maximum_length),
1270        "character" => PostgreSQLDataType::Char(character_maximum_length),
1271        "text" => PostgreSQLDataType::Text,
1272        "bytea" => PostgreSQLDataType::Bytea,
1273        "date" => PostgreSQLDataType::Date,
1274        "time without time zone" => PostgreSQLDataType::Time,
1275        "time with time zone" => PostgreSQLDataType::TimeWithTimeZone,
1276        "timestamp without time zone" => PostgreSQLDataType::Timestamp,
1277        "timestamp with time zone" => PostgreSQLDataType::TimestampWithTimeZone,
1278        "interval" => PostgreSQLDataType::Interval,
1279        "boolean" => PostgreSQLDataType::Boolean,
1280        "uuid" => PostgreSQLDataType::Uuid,
1281        "json" => PostgreSQLDataType::Json,
1282        "jsonb" => PostgreSQLDataType::Jsonb,
1283        "ARRAY" => {
1284            let base_type = parse_base_array_type(
1285                udt_name,
1286                column_default,
1287                column_name,
1288                table_name,
1289                pool,
1290                schema,
1291            )
1292            .await;
1293            PostgreSQLDataType::Array(Box::new(base_type))
1294        }
1295        "USER-DEFINED" => match udt_name {
1296            "geometry" => {
1297                let geo_info =
1298                    get_geometry_info(pool, schema, table_name, column_name, "geometry_columns")
1299                        .await;
1300                PostgreSQLDataType::Geometry(geo_info)
1301            }
1302            "geography" => {
1303                let geo_info =
1304                    get_geometry_info(pool, schema, table_name, column_name, "geography_columns")
1305                        .await;
1306                PostgreSQLDataType::Geography(geo_info)
1307            }
1308            _ => {
1309                if udt_name.starts_with("_") {
1310                    let base_udt = &udt_name[1..];
1311                    let base_type = match base_udt {
1312                        "geometry" => PostgreSQLDataType::Geometry(None),
1313                        "geography" => PostgreSQLDataType::Geography(None),
1314                        _ => PostgreSQLDataType::Custom(base_udt.to_string()),
1315                    };
1316                    PostgreSQLDataType::Array(Box::new(base_type))
1317                } else {
1318                    PostgreSQLDataType::Custom(udt_name.to_string())
1319                }
1320            }
1321        },
1322        _ => PostgreSQLDataType::Unknown(data_type_str.to_string()),
1323    }
1324}
1325
1326async fn parse_base_array_type(
1327    udt_name: &str,
1328    _column_default: &Option<String>,
1329    _column_name: &str,
1330    _table_name: &str,
1331    _pool: &PgPool,
1332    _schema: &str,
1333) -> PostgreSQLDataType {
1334    if udt_name.starts_with("_") {
1335        let base_type = &udt_name[1..];
1336        match base_type {
1337            "int2" => PostgreSQLDataType::SmallInt,
1338            "int4" => PostgreSQLDataType::Integer,
1339            "int8" => PostgreSQLDataType::BigInt,
1340            "float4" => PostgreSQLDataType::Real,
1341            "float8" => PostgreSQLDataType::DoublePrecision,
1342            "numeric" => PostgreSQLDataType::Numeric(None, None),
1343            "varchar" => PostgreSQLDataType::Varchar(None),
1344            "char" => PostgreSQLDataType::Char(None),
1345            "text" => PostgreSQLDataType::Text,
1346            "bytea" => PostgreSQLDataType::Bytea,
1347            "bool" => PostgreSQLDataType::Boolean,
1348            "uuid" => PostgreSQLDataType::Uuid,
1349            "json" => PostgreSQLDataType::Json,
1350            "jsonb" => PostgreSQLDataType::Jsonb,
1351            "geometry" => PostgreSQLDataType::Geometry(None),
1352            "geography" => PostgreSQLDataType::Geography(None),
1353            _ => PostgreSQLDataType::Custom(base_type.to_string()),
1354        }
1355    } else {
1356        PostgreSQLDataType::Unknown(udt_name.to_string())
1357    }
1358}
1359
1360async fn get_geometry_info(
1361    pool: &PgPool,
1362    schema: &str,
1363    table_name: &str,
1364    column_name: &str,
1365    metadata_table: &str,
1366) -> Option<GeometryInfo> {
1367    // geography_columns uses f_geography_column, geometry_columns uses f_geometry_column
1368    let column_field = if metadata_table == "geography_columns" {
1369        "f_geography_column"
1370    } else {
1371        "f_geometry_column"
1372    };
1373
1374    let query = format!(
1375        "SELECT type, srid, coord_dimension FROM {} WHERE f_table_schema = $1 AND f_table_name = $2 AND {} = $3",
1376        metadata_table, column_field
1377    );
1378
1379    if let Ok(row) = sqlx::query(&query)
1380        .bind(schema)
1381        .bind(table_name)
1382        .bind(column_name)
1383        .fetch_optional(pool)
1384        .await
1385    {
1386        if let Some(row) = row {
1387            let geometry_type_str: String = row.get("type");
1388            let srid: Option<i32> = row.get("srid");
1389            let dimension: Option<i32> = row.get("coord_dimension");
1390
1391            let geometry_type = match geometry_type_str.to_uppercase().as_str() {
1392                "POINT" => GeometryType::Point,
1393                "LINESTRING" => GeometryType::LineString,
1394                "POLYGON" => GeometryType::Polygon,
1395                "MULTIPOINT" => GeometryType::MultiPoint,
1396                "MULTILINESTRING" => GeometryType::MultiLineString,
1397                "MULTIPOLYGON" => GeometryType::MultiPolygon,
1398                "GEOMETRYCOLLECTION" => GeometryType::GeometryCollection,
1399                _ => return None,
1400            };
1401
1402            return Some(GeometryInfo {
1403                geometry_type,
1404                srid,
1405                dimension,
1406            });
1407        }
1408    }
1409
1410    None
1411}
1412
1413pub async fn get_foreign_key_constraints(
1414    pool: &PgPool,
1415    schema: &str,
1416    table: &str,
1417) -> Result<Vec<ForeignKeyConstraint>, sqlx::Error> {
1418    let query = r#"
1419        SELECT 
1420            rc.constraint_name,
1421            array_agg(kcu1.column_name ORDER BY kcu1.ordinal_position)::text as columns,
1422            kcu2.table_name as referenced_table,
1423            array_agg(kcu2.column_name ORDER BY kcu2.ordinal_position)::text as referenced_columns,
1424            rc.delete_rule as on_delete,
1425            rc.update_rule as on_update,
1426            tc.is_deferrable::boolean as is_deferrable,
1427            tc.initially_deferred::boolean as initially_deferred
1428        FROM information_schema.referential_constraints rc
1429        JOIN information_schema.key_column_usage kcu1
1430            ON rc.constraint_name = kcu1.constraint_name
1431            AND rc.constraint_schema = kcu1.constraint_schema
1432        JOIN information_schema.key_column_usage kcu2
1433            ON rc.unique_constraint_name = kcu2.constraint_name
1434            AND rc.unique_constraint_schema = kcu2.constraint_schema
1435            AND kcu1.ordinal_position = kcu2.ordinal_position
1436        JOIN information_schema.table_constraints tc
1437            ON rc.constraint_name = tc.constraint_name
1438            AND rc.constraint_schema = tc.constraint_schema
1439        WHERE kcu1.table_schema = $1
1440            AND kcu1.table_name = $2
1441        GROUP BY rc.constraint_name, kcu2.table_name, rc.delete_rule, rc.update_rule, 
1442                 tc.is_deferrable, tc.initially_deferred
1443        ORDER BY rc.constraint_name
1444    "#;
1445
1446    let rows = sqlx::query(query)
1447        .bind(schema)
1448        .bind(table)
1449        .fetch_all(pool)
1450        .await?;
1451
1452    let mut constraints = Vec::new();
1453    for row in rows {
1454        let constraint_name: String = row.get("constraint_name");
1455        let columns_str: String = row.get("columns");
1456        let columns = parse_postgres_array(&columns_str);
1457
1458        let referenced_table: String = row.get("referenced_table");
1459
1460        let referenced_columns_str: String = row.get("referenced_columns");
1461        let referenced_columns = parse_postgres_array(&referenced_columns_str);
1462        let on_delete: Option<String> = row.get("on_delete");
1463        let on_update: Option<String> = row.get("on_update");
1464        let is_deferrable: bool = row.get("is_deferrable");
1465        let initially_deferred: bool = row.get("initially_deferred");
1466
1467        let on_delete_action = on_delete.as_deref().and_then(|action| {
1468            if action == "NO ACTION" {
1469                None
1470            } else {
1471                ForeignKeyAction::from_str(action)
1472            }
1473        });
1474
1475        let on_update_action = on_update.as_deref().and_then(|action| {
1476            if action == "NO ACTION" {
1477                None
1478            } else {
1479                ForeignKeyAction::from_str(action)
1480            }
1481        });
1482
1483        constraints.push(ForeignKeyConstraint {
1484            constraint_name,
1485            columns,
1486            referenced_table,
1487            referenced_columns,
1488            on_delete: on_delete_action,
1489            on_update: on_update_action,
1490            is_deferrable,
1491            initially_deferred,
1492        });
1493    }
1494
1495    Ok(constraints)
1496}
1497
1498pub async fn get_table_indexes(
1499    pool: &PgPool,
1500    schema: &str,
1501    table: &str,
1502) -> Result<Vec<IndexInfo>, sqlx::Error> {
1503    let query = r#"
1504        SELECT 
1505            i.relname as index_name,
1506            array_agg(a.attname ORDER BY array_position(ix.indkey, a.attnum))::text as columns,
1507            ix.indisunique as is_unique,
1508            ix.indisprimary as is_primary,
1509            am.amname as index_type,
1510            pg_get_expr(ix.indpred, ix.indrelid) as condition
1511        FROM pg_index ix
1512        JOIN pg_class i ON i.oid = ix.indexrelid
1513        JOIN pg_class t ON t.oid = ix.indrelid
1514        JOIN pg_namespace n ON n.oid = t.relnamespace
1515        JOIN pg_am am ON am.oid = i.relam
1516        JOIN pg_attribute a ON a.attrelid = ix.indrelid AND a.attnum = ANY(ix.indkey)
1517        WHERE n.nspname = $1
1518            AND t.relname = $2
1519        GROUP BY i.relname, ix.indisunique, ix.indisprimary, am.amname, ix.indpred, ix.indrelid
1520        ORDER BY i.relname
1521    "#;
1522
1523    let rows = sqlx::query(query)
1524        .bind(schema)
1525        .bind(table)
1526        .fetch_all(pool)
1527        .await?;
1528
1529    let mut indexes = Vec::new();
1530    for row in rows {
1531        let index_name: String = row.get("index_name");
1532        let columns_str: String = row.get("columns");
1533        let columns = parse_postgres_array(&columns_str);
1534        let is_unique: bool = row.get("is_unique");
1535        let is_primary: bool = row.get("is_primary");
1536        let index_type_str: String = row.get("index_type");
1537        let index_type = IndexType::from_str(&index_type_str).unwrap_or(IndexType::BTree);
1538        let condition: Option<String> = row.get("condition");
1539
1540        indexes.push(IndexInfo {
1541            index_name,
1542            columns,
1543            is_unique,
1544            is_primary,
1545            index_type,
1546            condition,
1547        });
1548    }
1549
1550    Ok(indexes)
1551}
1552
1553pub async fn get_check_constraints(
1554    pool: &PgPool,
1555    schema: &str,
1556    table: &str,
1557) -> Result<Vec<CheckConstraint>, sqlx::Error> {
1558    let query = r#"
1559        SELECT 
1560            cc.constraint_name,
1561            cc.check_clause
1562        FROM information_schema.check_constraints cc
1563        JOIN information_schema.table_constraints tc
1564            ON cc.constraint_name = tc.constraint_name
1565            AND cc.constraint_schema = tc.constraint_schema
1566        WHERE tc.table_schema = $1
1567            AND tc.table_name = $2
1568            AND tc.constraint_type = 'CHECK'
1569        ORDER BY cc.constraint_name
1570    "#;
1571
1572    let rows = sqlx::query(query)
1573        .bind(schema)
1574        .bind(table)
1575        .fetch_all(pool)
1576        .await?;
1577
1578    let mut constraints = Vec::new();
1579    for row in rows {
1580        let constraint_name: String = row.get("constraint_name");
1581        let check_clause: String = row.get("check_clause");
1582
1583        // Skip system-generated NOT NULL constraints
1584        if is_not_null_constraint(&constraint_name, &check_clause) {
1585            continue;
1586        }
1587
1588        constraints.push(CheckConstraint {
1589            constraint_name,
1590            check_clause,
1591        });
1592    }
1593
1594    Ok(constraints)
1595}
1596
1597pub async fn get_table_comment(
1598    pool: &PgPool,
1599    schema: &str,
1600    table: &str,
1601) -> Result<Option<String>, sqlx::Error> {
1602    let query = r#"
1603        SELECT 
1604            pgd.description
1605        FROM pg_class pgc
1606        JOIN pg_namespace pgn ON pgn.oid = pgc.relnamespace
1607        LEFT JOIN pg_description pgd ON pgd.objoid = pgc.oid AND pgd.objsubid = 0
1608        WHERE pgn.nspname = $1 AND pgc.relname = $2
1609    "#;
1610
1611    let row = sqlx::query(query)
1612        .bind(schema)
1613        .bind(table)
1614        .fetch_optional(pool)
1615        .await?;
1616
1617    Ok(row.and_then(|r| r.get("description")))
1618}
1619
1620/// Check if a constraint is a system-generated NOT NULL constraint
1621fn is_not_null_constraint(constraint_name: &str, check_clause: &str) -> bool {
1622    // System-generated NOT NULL constraints typically have names like:
1623    // - {schema_oid}_{table_oid}_{column_number}_not_null
1624    // And check clauses like: (column_name IS NOT NULL)
1625
1626    if constraint_name.ends_with("_not_null") {
1627        // Check if the constraint name follows the pattern: numbers_numbers_numbers_not_null
1628        let parts: Vec<&str> = constraint_name.split('_').collect();
1629
1630        // Pattern is: numbers_numbers_numbers_not_null (5 parts total)
1631        if parts.len() == 5 && parts[3] == "not" && parts[4] == "null" {
1632            // Check if first 3 parts are all numbers
1633            if parts[0].chars().all(|c| c.is_ascii_digit())
1634                && parts[1].chars().all(|c| c.is_ascii_digit())
1635                && parts[2].chars().all(|c| c.is_ascii_digit())
1636            {
1637                // Also check if the check clause looks like a NOT NULL constraint
1638                return check_clause.contains("IS NOT NULL");
1639            }
1640        }
1641    }
1642
1643    false
1644}
1645
1646/// Check if an index is system-generated
1647pub fn is_system_generated_index(idx: &IndexInfo) -> bool {
1648    // System-generated indexes typically have names like:
1649    // - table_column_key (unique constraints)
1650    // - table_pkey (primary keys)
1651    // - constraint names starting with numbers (system-generated)
1652
1653    let name = &idx.index_name;
1654
1655    // Skip primary key indexes
1656    if idx.is_primary {
1657        return true;
1658    }
1659
1660    // Skip indexes with names that look system-generated
1661    if name.ends_with("_pkey")
1662        || name.contains("_not_null")
1663        || name.chars().next().map_or(false, |c| c.is_ascii_digit())
1664    {
1665        return true;
1666    }
1667
1668    // Allow UNIQUE constraint indexes (ending with _key) as they are user-defined constraints
1669    false
1670}
1671
1672/// Convert MySQL placeholder (?) to PostgreSQL placeholders ($1, $2, $3, ...)
1673///
1674/// This function efficiently converts MySQL-style question mark placeholders to PostgreSQL-style
1675/// numbered placeholders while respecting SQL string literals and comments.
1676///
1677/// # Examples
1678///
1679/// ```rust
1680/// use senax_pgsql_parser::convert_mysql_placeholders_to_postgresql;
1681///
1682/// let mysql_sql = "SELECT * FROM users WHERE id = ? AND name = ?";
1683/// let postgresql_sql = convert_mysql_placeholders_to_postgresql(mysql_sql);
1684/// assert_eq!(postgresql_sql, "SELECT * FROM users WHERE id = $1 AND name = $2");
1685///
1686/// // String literals are preserved
1687/// let mysql_sql = "SELECT * FROM users WHERE name = 'user?' AND id = ?";
1688/// let postgresql_sql = convert_mysql_placeholders_to_postgresql(mysql_sql);
1689/// assert_eq!(postgresql_sql, "SELECT * FROM users WHERE name = 'user?' AND id = $1");
1690/// ```
1691pub fn convert_mysql_placeholders_to_postgresql(sql: &str) -> String {
1692    let mut result = String::with_capacity(sql.len() + 32); // Pre-allocate with extra space for placeholders
1693    let mut chars = sql.chars().peekable();
1694    let mut placeholder_count = 0;
1695    let mut in_single_quote = false;
1696    let mut in_double_quote = false;
1697    let mut in_line_comment = false;
1698    let mut in_block_comment = false;
1699
1700    while let Some(ch) = chars.next() {
1701        match ch {
1702            // Handle string literals
1703            '\'' if !in_double_quote && !in_line_comment && !in_block_comment => {
1704                in_single_quote = !in_single_quote;
1705                result.push(ch);
1706            }
1707            '"' if !in_single_quote && !in_line_comment && !in_block_comment => {
1708                in_double_quote = !in_double_quote;
1709                result.push(ch);
1710            }
1711
1712            // Handle SQL comments
1713            '-' if !in_single_quote && !in_double_quote && !in_block_comment => {
1714                if chars.peek() == Some(&'-') {
1715                    chars.next(); // consume second '-'
1716                    in_line_comment = true;
1717                    result.push_str("--");
1718                } else {
1719                    result.push(ch);
1720                }
1721            }
1722            '/' if !in_single_quote && !in_double_quote && !in_line_comment => {
1723                if chars.peek() == Some(&'*') {
1724                    chars.next(); // consume '*'
1725                    in_block_comment = true;
1726                    result.push_str("/*");
1727                } else {
1728                    result.push(ch);
1729                }
1730            }
1731            '*' if in_block_comment => {
1732                if chars.peek() == Some(&'/') {
1733                    chars.next(); // consume '/'
1734                    in_block_comment = false;
1735                    result.push_str("*/");
1736                } else {
1737                    result.push(ch);
1738                }
1739            }
1740            '\n' | '\r' if in_line_comment => {
1741                in_line_comment = false;
1742                result.push(ch);
1743            }
1744
1745            // Handle escape sequences in string literals
1746            '\\' if (in_single_quote || in_double_quote)
1747                && !in_line_comment
1748                && !in_block_comment =>
1749            {
1750                result.push(ch);
1751                if let Some(next_ch) = chars.next() {
1752                    result.push(next_ch); // Push the escaped character as-is
1753                }
1754            }
1755
1756            // Handle placeholder conversion
1757            '?' if !in_single_quote
1758                && !in_double_quote
1759                && !in_line_comment
1760                && !in_block_comment =>
1761            {
1762                placeholder_count += 1;
1763                result.push('$');
1764                result.push_str(&placeholder_count.to_string());
1765            }
1766
1767            // Default case: just push the character
1768            _ => {
1769                result.push(ch);
1770            }
1771        }
1772    }
1773
1774    result
1775}
1776
1777pub fn escape_db_identifier(s: &str) -> String {
1778    format!(r#""{}""#, s.replace('"', r#""""#))
1779}