vespertide_query/sql/
modify_column_comment.rs

1use sea_query::Alias;
2
3use vespertide_core::TableDef;
4
5use super::helpers::build_sea_column_def_with_table;
6use super::types::{BuiltQuery, DatabaseBackend, RawSql};
7use crate::error::QueryError;
8
9/// Build SQL for changing column comment.
10/// Note: SQLite does not support column comments natively.
11pub fn build_modify_column_comment(
12    backend: &DatabaseBackend,
13    table: &str,
14    column: &str,
15    new_comment: Option<&str>,
16    current_schema: &[TableDef],
17) -> Result<Vec<BuiltQuery>, QueryError> {
18    let mut queries = Vec::new();
19
20    match backend {
21        DatabaseBackend::Postgres => {
22            let comment_sql = if let Some(comment) = new_comment {
23                // Escape single quotes in comment
24                let escaped = comment.replace('\'', "''");
25                format!(
26                    "COMMENT ON COLUMN \"{}\".\"{}\" IS '{}'",
27                    table, column, escaped
28                )
29            } else {
30                format!("COMMENT ON COLUMN \"{}\".\"{}\" IS NULL", table, column)
31            };
32            queries.push(BuiltQuery::Raw(RawSql::uniform(comment_sql)));
33        }
34        DatabaseBackend::MySql => {
35            // MySQL requires the full column definition in MODIFY COLUMN to change comment
36            let table_def = current_schema
37                .iter()
38                .find(|t| t.name == table)
39                .ok_or_else(|| {
40                    QueryError::Other(format!("Table '{}' not found in current schema.", table))
41                })?;
42
43            let column_def = table_def
44                .columns
45                .iter()
46                .find(|c| c.name == column)
47                .ok_or_else(|| {
48                    QueryError::Other(format!(
49                        "Column '{}' not found in table '{}'.",
50                        column, table
51                    ))
52                })?;
53
54            // Build the full column definition with updated comment
55            let modified_col_def = vespertide_core::ColumnDef {
56                comment: new_comment.map(|s| s.to_string()),
57                ..column_def.clone()
58            };
59
60            // Build base ALTER TABLE statement using sea-query for type/nullable/default
61            let sea_col = build_sea_column_def_with_table(backend, table, &modified_col_def);
62
63            // Build the ALTER TABLE ... MODIFY COLUMN statement
64            let stmt = sea_query::Table::alter()
65                .table(Alias::new(table))
66                .modify_column(sea_col)
67                .to_owned();
68
69            // Get the base SQL from sea-query
70            let base_sql = super::helpers::build_schema_statement(&stmt, *backend);
71
72            // Add COMMENT clause if needed (sea-query doesn't support COMMENT)
73            let final_sql = if let Some(comment) = new_comment {
74                let escaped = comment.replace('\'', "''");
75                format!("{} COMMENT '{}'", base_sql, escaped)
76            } else {
77                base_sql
78            };
79
80            queries.push(BuiltQuery::Raw(RawSql::uniform(final_sql)));
81        }
82        DatabaseBackend::Sqlite => {
83            // SQLite doesn't support column comments
84            // We could store the comment in a separate table or just ignore it
85            // For now, we'll skip this operation for SQLite since it doesn't affect the schema
86            // Just update the internal schema representation (handled by apply.rs)
87        }
88    }
89
90    Ok(queries)
91}
92
93#[cfg(test)]
94mod tests {
95    use super::*;
96    use insta::{assert_snapshot, with_settings};
97    use rstest::rstest;
98    use vespertide_core::{ColumnDef, ColumnType, SimpleColumnType, TableConstraint};
99
100    fn col(name: &str, ty: ColumnType, nullable: bool) -> ColumnDef {
101        ColumnDef {
102            name: name.to_string(),
103            r#type: ty,
104            nullable,
105            default: None,
106            comment: None,
107            primary_key: None,
108            unique: None,
109            index: None,
110            foreign_key: None,
111        }
112    }
113
114    fn table_def(
115        name: &str,
116        columns: Vec<ColumnDef>,
117        constraints: Vec<TableConstraint>,
118    ) -> TableDef {
119        TableDef {
120            name: name.to_string(),
121            description: None,
122            columns,
123            constraints,
124        }
125    }
126
127    #[rstest]
128    #[case::postgres_set_comment(DatabaseBackend::Postgres, Some("User email address"))]
129    #[case::postgres_drop_comment(DatabaseBackend::Postgres, None)]
130    #[case::mysql_set_comment(DatabaseBackend::MySql, Some("User email address"))]
131    #[case::mysql_drop_comment(DatabaseBackend::MySql, None)]
132    #[case::sqlite_set_comment(DatabaseBackend::Sqlite, Some("User email address"))]
133    #[case::sqlite_drop_comment(DatabaseBackend::Sqlite, None)]
134    fn test_build_modify_column_comment(
135        #[case] backend: DatabaseBackend,
136        #[case] new_comment: Option<&str>,
137    ) {
138        let schema = vec![table_def(
139            "users",
140            vec![
141                col("id", ColumnType::Simple(SimpleColumnType::Integer), false),
142                col("email", ColumnType::Simple(SimpleColumnType::Text), true),
143            ],
144            vec![],
145        )];
146
147        let result = build_modify_column_comment(&backend, "users", "email", new_comment, &schema);
148        assert!(result.is_ok());
149        let queries = result.unwrap();
150        let sql = queries
151            .iter()
152            .map(|q| q.build(backend))
153            .collect::<Vec<String>>()
154            .join("\n");
155
156        let suffix = format!(
157            "{}_{}_users",
158            match backend {
159                DatabaseBackend::Postgres => "postgres",
160                DatabaseBackend::MySql => "mysql",
161                DatabaseBackend::Sqlite => "sqlite",
162            },
163            if new_comment.is_some() {
164                "set_comment"
165            } else {
166                "drop_comment"
167            }
168        );
169
170        with_settings!({ snapshot_suffix => suffix }, {
171            assert_snapshot!(sql);
172        });
173    }
174
175    /// Test comment with quotes escaping
176    #[rstest]
177    #[case::postgres_comment_with_quotes(DatabaseBackend::Postgres)]
178    #[case::mysql_comment_with_quotes(DatabaseBackend::MySql)]
179    #[case::sqlite_comment_with_quotes(DatabaseBackend::Sqlite)]
180    fn test_comment_with_quotes(#[case] backend: DatabaseBackend) {
181        let schema = vec![table_def(
182            "users",
183            vec![col(
184                "email",
185                ColumnType::Simple(SimpleColumnType::Text),
186                true,
187            )],
188            vec![],
189        )];
190
191        let result = build_modify_column_comment(
192            &backend,
193            "users",
194            "email",
195            Some("User's email address"),
196            &schema,
197        );
198        assert!(result.is_ok());
199        let queries = result.unwrap();
200        let sql = queries
201            .iter()
202            .map(|q| q.build(backend))
203            .collect::<Vec<String>>()
204            .join("\n");
205
206        // Postgres and MySQL should escape quotes, SQLite returns empty
207        if backend != DatabaseBackend::Sqlite {
208            assert!(
209                sql.contains("User''s email address"),
210                "Should escape single quotes"
211            );
212        }
213
214        let suffix = format!(
215            "{}_comment_with_quotes",
216            match backend {
217                DatabaseBackend::Postgres => "postgres",
218                DatabaseBackend::MySql => "mysql",
219                DatabaseBackend::Sqlite => "sqlite",
220            }
221        );
222
223        with_settings!({ snapshot_suffix => suffix }, {
224            assert_snapshot!(sql);
225        });
226    }
227
228    /// Test table not found error
229    #[rstest]
230    #[case::postgres_table_not_found(DatabaseBackend::Postgres)]
231    #[case::mysql_table_not_found(DatabaseBackend::MySql)]
232    #[case::sqlite_table_not_found(DatabaseBackend::Sqlite)]
233    fn test_table_not_found(#[case] backend: DatabaseBackend) {
234        // Postgres and SQLite don't need schema lookup, so skip this test for them
235        if backend == DatabaseBackend::Postgres || backend == DatabaseBackend::Sqlite {
236            return;
237        }
238
239        let result = build_modify_column_comment(&backend, "users", "email", Some("comment"), &[]);
240        assert!(result.is_err());
241        let err_msg = result.unwrap_err().to_string();
242        assert!(err_msg.contains("Table 'users' not found"));
243    }
244
245    /// Test column not found error
246    #[rstest]
247    #[case::postgres_column_not_found(DatabaseBackend::Postgres)]
248    #[case::mysql_column_not_found(DatabaseBackend::MySql)]
249    #[case::sqlite_column_not_found(DatabaseBackend::Sqlite)]
250    fn test_column_not_found(#[case] backend: DatabaseBackend) {
251        // Postgres and SQLite don't need schema lookup, so skip this test for them
252        if backend == DatabaseBackend::Postgres || backend == DatabaseBackend::Sqlite {
253            return;
254        }
255
256        let schema = vec![table_def(
257            "users",
258            vec![col(
259                "id",
260                ColumnType::Simple(SimpleColumnType::Integer),
261                false,
262            )],
263            vec![],
264        )];
265
266        let result =
267            build_modify_column_comment(&backend, "users", "email", Some("comment"), &schema);
268        assert!(result.is_err());
269        let err_msg = result.unwrap_err().to_string();
270        assert!(err_msg.contains("Column 'email' not found"));
271    }
272
273    /// Test with long comment
274    #[rstest]
275    #[case::postgres_long_comment(DatabaseBackend::Postgres)]
276    #[case::mysql_long_comment(DatabaseBackend::MySql)]
277    #[case::sqlite_long_comment(DatabaseBackend::Sqlite)]
278    fn test_long_comment(#[case] backend: DatabaseBackend) {
279        let schema = vec![table_def(
280            "users",
281            vec![col("bio", ColumnType::Simple(SimpleColumnType::Text), true)],
282            vec![],
283        )];
284
285        let long_comment = "This is a very long comment that describes the bio field in great detail. It contains multiple sentences and provides thorough documentation for this column.";
286
287        let result =
288            build_modify_column_comment(&backend, "users", "bio", Some(long_comment), &schema);
289        assert!(result.is_ok());
290        let queries = result.unwrap();
291        let sql = queries
292            .iter()
293            .map(|q| q.build(backend))
294            .collect::<Vec<String>>()
295            .join("\n");
296
297        let suffix = format!(
298            "{}_long_comment",
299            match backend {
300                DatabaseBackend::Postgres => "postgres",
301                DatabaseBackend::MySql => "mysql",
302                DatabaseBackend::Sqlite => "sqlite",
303            }
304        );
305
306        with_settings!({ snapshot_suffix => suffix }, {
307            assert_snapshot!(sql);
308        });
309    }
310
311    /// Test preserves column properties when modifying comment
312    #[rstest]
313    #[case::postgres_preserves_properties(DatabaseBackend::Postgres)]
314    #[case::mysql_preserves_properties(DatabaseBackend::MySql)]
315    #[case::sqlite_preserves_properties(DatabaseBackend::Sqlite)]
316    fn test_preserves_column_properties(#[case] backend: DatabaseBackend) {
317        let mut email_col = col("email", ColumnType::Simple(SimpleColumnType::Text), true);
318        email_col.default = Some("'default@example.com'".into());
319
320        let schema = vec![table_def(
321            "users",
322            vec![
323                col("id", ColumnType::Simple(SimpleColumnType::Integer), false),
324                email_col,
325            ],
326            vec![],
327        )];
328
329        let result = build_modify_column_comment(
330            &backend,
331            "users",
332            "email",
333            Some("User email address"),
334            &schema,
335        );
336        assert!(result.is_ok());
337        let queries = result.unwrap();
338        let sql = queries
339            .iter()
340            .map(|q| q.build(backend))
341            .collect::<Vec<String>>()
342            .join("\n");
343
344        // MySQL should preserve the default value in the MODIFY COLUMN statement
345        if backend == DatabaseBackend::MySql {
346            assert!(sql.contains("DEFAULT"), "Should preserve DEFAULT clause");
347        }
348
349        let suffix = format!(
350            "{}_preserves_properties",
351            match backend {
352                DatabaseBackend::Postgres => "postgres",
353                DatabaseBackend::MySql => "mysql",
354                DatabaseBackend::Sqlite => "sqlite",
355            }
356        );
357
358        with_settings!({ snapshot_suffix => suffix }, {
359            assert_snapshot!(sql);
360        });
361    }
362
363    /// Test changing comment from one value to another
364    #[rstest]
365    #[case::postgres_change_comment(DatabaseBackend::Postgres)]
366    #[case::mysql_change_comment(DatabaseBackend::MySql)]
367    #[case::sqlite_change_comment(DatabaseBackend::Sqlite)]
368    fn test_change_comment(#[case] backend: DatabaseBackend) {
369        let mut email_col = col("email", ColumnType::Simple(SimpleColumnType::Text), true);
370        email_col.comment = Some("Old comment".into());
371
372        let schema = vec![table_def(
373            "users",
374            vec![
375                col("id", ColumnType::Simple(SimpleColumnType::Integer), false),
376                email_col,
377            ],
378            vec![],
379        )];
380
381        let result =
382            build_modify_column_comment(&backend, "users", "email", Some("New comment"), &schema);
383        assert!(result.is_ok());
384        let queries = result.unwrap();
385        let sql = queries
386            .iter()
387            .map(|q| q.build(backend))
388            .collect::<Vec<String>>()
389            .join("\n");
390
391        let suffix = format!(
392            "{}_change_comment",
393            match backend {
394                DatabaseBackend::Postgres => "postgres",
395                DatabaseBackend::MySql => "mysql",
396                DatabaseBackend::Sqlite => "sqlite",
397            }
398        );
399
400        with_settings!({ snapshot_suffix => suffix }, {
401            assert_snapshot!(sql);
402        });
403    }
404
405    /// Test dropping existing comment
406    #[rstest]
407    #[case::postgres_drop_existing_comment(DatabaseBackend::Postgres)]
408    #[case::mysql_drop_existing_comment(DatabaseBackend::MySql)]
409    #[case::sqlite_drop_existing_comment(DatabaseBackend::Sqlite)]
410    fn test_drop_existing_comment(#[case] backend: DatabaseBackend) {
411        let mut email_col = col("email", ColumnType::Simple(SimpleColumnType::Text), true);
412        email_col.comment = Some("Existing comment".into());
413
414        let schema = vec![table_def(
415            "users",
416            vec![
417                col("id", ColumnType::Simple(SimpleColumnType::Integer), false),
418                email_col,
419            ],
420            vec![],
421        )];
422
423        let result = build_modify_column_comment(
424            &backend, "users", "email", None, // Drop comment
425            &schema,
426        );
427        assert!(result.is_ok());
428        let queries = result.unwrap();
429        let sql = queries
430            .iter()
431            .map(|q| q.build(backend))
432            .collect::<Vec<String>>()
433            .join("\n");
434
435        let suffix = format!(
436            "{}_drop_existing_comment",
437            match backend {
438                DatabaseBackend::Postgres => "postgres",
439                DatabaseBackend::MySql => "mysql",
440                DatabaseBackend::Sqlite => "sqlite",
441            }
442        );
443
444        with_settings!({ snapshot_suffix => suffix }, {
445            assert_snapshot!(sql);
446        });
447    }
448
449    /// Test with different column types
450    #[rstest]
451    #[case::postgres_integer_column(
452        DatabaseBackend::Postgres,
453        SimpleColumnType::Integer,
454        "Auto-increment ID"
455    )]
456    #[case::mysql_integer_column(
457        DatabaseBackend::MySql,
458        SimpleColumnType::Integer,
459        "Auto-increment ID"
460    )]
461    #[case::sqlite_integer_column(
462        DatabaseBackend::Sqlite,
463        SimpleColumnType::Integer,
464        "Auto-increment ID"
465    )]
466    #[case::postgres_boolean_column(
467        DatabaseBackend::Postgres,
468        SimpleColumnType::Boolean,
469        "Is user active"
470    )]
471    #[case::mysql_boolean_column(
472        DatabaseBackend::MySql,
473        SimpleColumnType::Boolean,
474        "Is user active"
475    )]
476    #[case::sqlite_boolean_column(
477        DatabaseBackend::Sqlite,
478        SimpleColumnType::Boolean,
479        "Is user active"
480    )]
481    #[case::postgres_timestamp_column(
482        DatabaseBackend::Postgres,
483        SimpleColumnType::Timestamp,
484        "Creation timestamp"
485    )]
486    #[case::mysql_timestamp_column(
487        DatabaseBackend::MySql,
488        SimpleColumnType::Timestamp,
489        "Creation timestamp"
490    )]
491    #[case::sqlite_timestamp_column(
492        DatabaseBackend::Sqlite,
493        SimpleColumnType::Timestamp,
494        "Creation timestamp"
495    )]
496    fn test_comment_on_different_types(
497        #[case] backend: DatabaseBackend,
498        #[case] column_type: SimpleColumnType,
499        #[case] comment: &str,
500    ) {
501        let schema = vec![table_def(
502            "data",
503            vec![col("field", ColumnType::Simple(column_type.clone()), false)],
504            vec![],
505        )];
506
507        let result = build_modify_column_comment(&backend, "data", "field", Some(comment), &schema);
508        assert!(result.is_ok());
509        let queries = result.unwrap();
510        let sql = queries
511            .iter()
512            .map(|q| q.build(backend))
513            .collect::<Vec<String>>()
514            .join("\n");
515
516        let type_name = format!("{:?}", column_type).to_lowercase();
517        let suffix = format!(
518            "{}_{}_comment",
519            match backend {
520                DatabaseBackend::Postgres => "postgres",
521                DatabaseBackend::MySql => "mysql",
522                DatabaseBackend::Sqlite => "sqlite",
523            },
524            type_name
525        );
526
527        with_settings!({ snapshot_suffix => suffix }, {
528            assert_snapshot!(sql);
529        });
530    }
531
532    /// Test with NOT NULL column
533    #[rstest]
534    #[case::postgres_not_null_column(DatabaseBackend::Postgres)]
535    #[case::mysql_not_null_column(DatabaseBackend::MySql)]
536    #[case::sqlite_not_null_column(DatabaseBackend::Sqlite)]
537    fn test_comment_on_not_null_column(#[case] backend: DatabaseBackend) {
538        let schema = vec![table_def(
539            "users",
540            vec![col(
541                "username",
542                ColumnType::Simple(SimpleColumnType::Text),
543                false,
544            )],
545            vec![],
546        )];
547
548        let result = build_modify_column_comment(
549            &backend,
550            "users",
551            "username",
552            Some("Required username"),
553            &schema,
554        );
555        assert!(result.is_ok());
556        let queries = result.unwrap();
557        let sql = queries
558            .iter()
559            .map(|q| q.build(backend))
560            .collect::<Vec<String>>()
561            .join("\n");
562
563        let suffix = format!(
564            "{}_not_null_column",
565            match backend {
566                DatabaseBackend::Postgres => "postgres",
567                DatabaseBackend::MySql => "mysql",
568                DatabaseBackend::Sqlite => "sqlite",
569            }
570        );
571
572        with_settings!({ snapshot_suffix => suffix }, {
573            assert_snapshot!(sql);
574        });
575    }
576}