diff --git a/libs/sql-ddl/src/postgres.rs b/libs/sql-ddl/src/postgres.rs index 7bd075adc748..8dfecffbd206 100644 --- a/libs/sql-ddl/src/postgres.rs +++ b/libs/sql-ddl/src/postgres.rs @@ -347,6 +347,7 @@ pub struct CreateIndex<'a> { pub table_reference: &'a dyn Display, pub columns: Vec>, pub using: Option, + pub where_clause: Option<&'a str>, } impl Display for CreateIndex<'_> { @@ -388,7 +389,13 @@ impl Display for CreateIndex<'_> { }) .join(", ", f)?; - f.write_str(")") + f.write_str(")")?; + + if let Some(where_clause) = self.where_clause { + write!(f, " WHERE {where_clause}")?; + } + + Ok(()) } } @@ -432,6 +439,7 @@ mod tests { table_reference: &PostgresIdentifier::Simple(Cow::Borrowed("Cat")), columns, using: None, + where_clause: None, }; assert_eq!( @@ -450,6 +458,7 @@ mod tests { table_reference: &PostgresIdentifier::Simple(Cow::Borrowed("Cat")), columns, using: Some(IndexAlgorithm::Hash), + where_clause: None, }; assert_eq!( @@ -479,6 +488,7 @@ mod tests { table_reference: &PostgresIdentifier::Simple("Cat".into()), columns, using: None, + where_clause: None, }; assert_eq!( diff --git a/psl/parser-database/src/attributes.rs b/psl/parser-database/src/attributes.rs index dfc0f41561ed..4170b86cfb1e 100644 --- a/psl/parser-database/src/attributes.rs +++ b/psl/parser-database/src/attributes.rs @@ -537,6 +537,20 @@ fn model_index(data: &mut ModelAttributes, model_id: crate::ModelId, ctx: &mut C index_attribute.algorithm = algo; index_attribute.clustered = validate_clustering_setting(ctx); + let where_clause = match ctx + .visit_optional_arg("where") + .and_then(|expr| coerce::string(expr, ctx.diagnostics)) + { + Some("") => { + ctx.push_attribute_validation_error("The `where` argument cannot be an empty string."); + None + } + Some(clause) => Some(ctx.interner.intern(clause)), + None => None, + }; + + index_attribute.where_clause = where_clause; + data.ast_indexes.push((ctx.current_attribute_id().1, index_attribute)); } @@ -593,6 +607,20 @@ fn model_unique(data: &mut ModelAttributes, model_id: crate::ModelId, ctx: &mut index_attribute.mapped_name = mapped_name; index_attribute.clustered = validate_clustering_setting(ctx); + let where_clause = match ctx + .visit_optional_arg("where") + .and_then(|expr| coerce::string(expr, ctx.diagnostics)) + { + Some("") => { + ctx.push_attribute_validation_error("The `where` argument cannot be an empty string."); + None + } + Some(clause) => Some(ctx.interner.intern(clause)), + None => None, + }; + + index_attribute.where_clause = where_clause; + data.ast_indexes.push((current_attribute_id.1, index_attribute)); } diff --git a/psl/parser-database/src/types.rs b/psl/parser-database/src/types.rs index 2081e0337ec5..1552cd902e85 100644 --- a/psl/parser-database/src/types.rs +++ b/psl/parser-database/src/types.rs @@ -493,6 +493,7 @@ pub(crate) struct IndexAttribute { pub(crate) mapped_name: Option, pub(crate) algorithm: Option, pub(crate) clustered: Option, + pub(crate) where_clause: Option, } impl IndexAttribute { diff --git a/psl/parser-database/src/walkers/index.rs b/psl/parser-database/src/walkers/index.rs index b62a9c4ddc83..c4a3b434d7df 100644 --- a/psl/parser-database/src/walkers/index.rs +++ b/psl/parser-database/src/walkers/index.rs @@ -177,6 +177,11 @@ impl<'db> IndexWalker<'db> { self.index_attribute.clustered } + /// The WHERE clause of the partial index, if any. + pub fn where_clause(self) -> Option<&'db str> { + self.index_attribute.where_clause.map(|id| &self.db[id]) + } + /// The model the index is defined on. pub fn model(self) -> ModelWalker<'db> { self.db.walk(self.model_id) diff --git a/psl/psl-core/src/common/preview_features.rs b/psl/psl-core/src/common/preview_features.rs index 61f6652a2115..3f6acb749246 100644 --- a/psl/psl-core/src/common/preview_features.rs +++ b/psl/psl-core/src/common/preview_features.rs @@ -73,6 +73,7 @@ features!( OrderByAggregateGroup, OrderByNulls, OrderByRelation, + PartialIndexes, PostgresqlExtensions, PrismaSchemaFolder, QueryCompiler, @@ -156,6 +157,7 @@ impl<'a> FeatureMapWithProvider<'a> { DriverAdapters | Metrics | NativeDistinct + | PartialIndexes | PostgresqlExtensions | QueryCompiler | RelationJoins diff --git a/psl/psl-core/src/validate/validation_pipeline/validations.rs b/psl/psl-core/src/validate/validation_pipeline/validations.rs index e4b9c1c99d98..dc7595116805 100644 --- a/psl/psl-core/src/validate/validation_pipeline/validations.rs +++ b/psl/psl-core/src/validate/validation_pipeline/validations.rs @@ -138,6 +138,7 @@ pub(super) fn validate(ctx: &mut Context<'_>) { indexes::clustering_can_be_defined_only_once(index, ctx); indexes::opclasses_are_not_allowed_with_other_than_normal_indices(index, ctx); indexes::composite_type_in_compound_unique_index(index, ctx); + indexes::partial_index_is_supported(index, ctx); for field_attribute in index.scalar_field_attributes() { let span = index.ast_attribute().span; diff --git a/psl/psl-core/src/validate/validation_pipeline/validations/indexes.rs b/psl/psl-core/src/validate/validation_pipeline/validations/indexes.rs index ea6271cd1954..27c46de1f57e 100644 --- a/psl/psl-core/src/validate/validation_pipeline/validations/indexes.rs +++ b/psl/psl-core/src/validate/validation_pipeline/validations/indexes.rs @@ -1,5 +1,6 @@ use super::{constraint_namespace::ConstraintName, database_name::validate_db_name}; use crate::{ + PreviewFeature, datamodel_connector::{ConnectorCapability, walker_ext_traits::*}, diagnostics::DatamodelError, validate::validation_pipeline::context::Context, @@ -398,3 +399,35 @@ pub(super) fn unique_client_name_does_not_clash_with_field(index: IndexWalker<'_ )); } } + +/// Partial indexes are only supported on PostgreSQL and CockroachDB with the partialIndexes preview feature. +pub(crate) fn partial_index_is_supported(index: IndexWalker<'_>, ctx: &mut Context<'_>) { + if index.where_clause().is_none() { + return; + } + + if !ctx.preview_features.contains(PreviewFeature::PartialIndexes) { + let message = "You have a partial index definition. Partial indexes are currently a preview feature. To use partial indexes, please add \"partialIndexes\" to the preview features."; + + ctx.push_error(DatamodelError::new_attribute_validation_error( + message, + index.attribute_name(), + index.ast_attribute().span, + )); + + return; + } + + let connector_name = ctx.connector.provider_name(); + if !matches!(connector_name, "postgresql" | "cockroachdb") { + let message = format!( + "Partial indexes are only supported on PostgreSQL and CockroachDB. Your connector is `{connector_name}`." + ); + + ctx.push_error(DatamodelError::new_attribute_validation_error( + &message, + index.attribute_name(), + index.ast_attribute().span, + )); + } +} diff --git a/psl/psl/tests/config/generators.rs b/psl/psl/tests/config/generators.rs index 5f0f452bf1d4..10b06814f0e0 100644 --- a/psl/psl/tests/config/generators.rs +++ b/psl/psl/tests/config/generators.rs @@ -256,7 +256,7 @@ fn nice_error_for_unknown_generator_preview_feature() { .unwrap_err(); let expectation = expect![[r#" - error: The preview feature "foo" is not known. Expected one of: driverAdapters, metrics, nativeDistinct, postgresqlExtensions, queryCompiler, relationJoins, shardKeys, strictUndefinedChecks, views + error: The preview feature "foo" is not known. Expected one of: driverAdapters, metrics, nativeDistinct, partialIndexes, postgresqlExtensions, queryCompiler, relationJoins, shardKeys, strictUndefinedChecks, views --> schema.prisma:3  |   2 |  provider = "prisma-client-js" diff --git a/psl/psl/tests/validation/preview_features/native_full_text_search_postgres/mysql.prisma b/psl/psl/tests/validation/preview_features/native_full_text_search_postgres/mysql.prisma index 9d65b52f005a..21617f2eb001 100644 --- a/psl/psl/tests/validation/preview_features/native_full_text_search_postgres/mysql.prisma +++ b/psl/psl/tests/validation/preview_features/native_full_text_search_postgres/mysql.prisma @@ -14,7 +14,7 @@ model Blog { title String @@fulltext([content, title]) } -// error: The preview feature "fullTextSearchPostgres" is not known. Expected one of: driverAdapters, metrics, nativeDistinct, postgresqlExtensions, queryCompiler, relationJoins, shardKeys, strictUndefinedChecks, views +// error: The preview feature "fullTextSearchPostgres" is not known. Expected one of: driverAdapters, metrics, nativeDistinct, partialIndexes, postgresqlExtensions, queryCompiler, relationJoins, shardKeys, strictUndefinedChecks, views // --> schema.prisma:3 //  |  //  2 |  provider = "prisma-client-js" diff --git a/psl/psl/tests/validation/preview_features/partial_indexes/cockroachdb_basic.prisma b/psl/psl/tests/validation/preview_features/partial_indexes/cockroachdb_basic.prisma new file mode 100644 index 000000000000..9097141d57ea --- /dev/null +++ b/psl/psl/tests/validation/preview_features/partial_indexes/cockroachdb_basic.prisma @@ -0,0 +1,20 @@ +generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +datasource db { + provider = "cockroachdb" + url = env("DATABASE_URL") +} + +model Post { + id Int @id + title String + content String? + published Boolean @default(false) + authorId Int + + @@index([title], where: "published = true") + @@unique([authorId, title], where: "published = true") +} diff --git a/psl/psl/tests/validation/preview_features/partial_indexes/empty_where_clause.prisma b/psl/psl/tests/validation/preview_features/partial_indexes/empty_where_clause.prisma new file mode 100644 index 000000000000..3b631b5c5e10 --- /dev/null +++ b/psl/psl/tests/validation/preview_features/partial_indexes/empty_where_clause.prisma @@ -0,0 +1,23 @@ +generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +datasource db { + provider = "postgresql" + url = env("DATABASE_URL") +} + +model User { + id Int @id + email String @unique + isActive Boolean @default(true) + + @@index([email], where: "") +} +// error: Error parsing attribute "@index": The `where` argument cannot be an empty string. +// --> schema.prisma:16 +//  |  +// 15 |  +// 16 |  @@index([email], where: "") +//  |  diff --git a/psl/psl/tests/validation/preview_features/partial_indexes/empty_where_clause_unique.prisma b/psl/psl/tests/validation/preview_features/partial_indexes/empty_where_clause_unique.prisma new file mode 100644 index 000000000000..a435c91feabf --- /dev/null +++ b/psl/psl/tests/validation/preview_features/partial_indexes/empty_where_clause_unique.prisma @@ -0,0 +1,23 @@ +generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +datasource db { + provider = "postgresql" + url = env("DATABASE_URL") +} + +model User { + id Int @id + email String @unique + isActive Boolean @default(true) + + @@unique([email], where: "") +} +// error: Error parsing attribute "@unique": The `where` argument cannot be an empty string. +// --> schema.prisma:16 +//  |  +// 15 |  +// 16 |  @@unique([email], where: "") +//  |  diff --git a/psl/psl/tests/validation/preview_features/partial_indexes/mysql_unsupported.prisma b/psl/psl/tests/validation/preview_features/partial_indexes/mysql_unsupported.prisma new file mode 100644 index 000000000000..1cab3c37015a --- /dev/null +++ b/psl/psl/tests/validation/preview_features/partial_indexes/mysql_unsupported.prisma @@ -0,0 +1,23 @@ +generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +datasource db { + provider = "mysql" + url = env("DATABASE_URL") +} + +model User { + id Int @id + email String @unique + isActive Boolean @default(true) + + @@index([email], where: "isActive = true") +} +// error: Error parsing attribute "@@index": Partial indexes are only supported on PostgreSQL and CockroachDB. Your connector is `mysql`. +// --> schema.prisma:16 +//  |  +// 15 |  +// 16 |  @@index([email], where: "isActive = true") +//  |  diff --git a/psl/psl/tests/validation/preview_features/partial_indexes/no_preview_feature.prisma b/psl/psl/tests/validation/preview_features/partial_indexes/no_preview_feature.prisma new file mode 100644 index 000000000000..3db64bb4f7e1 --- /dev/null +++ b/psl/psl/tests/validation/preview_features/partial_indexes/no_preview_feature.prisma @@ -0,0 +1,22 @@ +generator client { + provider = "prisma-client-js" +} + +datasource db { + provider = "postgresql" + url = env("DATABASE_URL") +} + +model User { + id Int @id + email String @unique + isActive Boolean @default(true) + + @@index([email], where: "isActive = true") +} +// error: Error parsing attribute "@@index": You have a partial index definition. Partial indexes are currently a preview feature. To use partial indexes, please add "partialIndexes" to the preview features. +// --> schema.prisma:15 +//  |  +// 14 |  +// 15 |  @@index([email], where: "isActive = true") +//  |  diff --git a/psl/psl/tests/validation/preview_features/partial_indexes/postgresql_basic.prisma b/psl/psl/tests/validation/preview_features/partial_indexes/postgresql_basic.prisma new file mode 100644 index 000000000000..f2ab1a55976f --- /dev/null +++ b/psl/psl/tests/validation/preview_features/partial_indexes/postgresql_basic.prisma @@ -0,0 +1,19 @@ +generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +datasource db { + provider = "postgresql" + url = env("DATABASE_URL") +} + +model User { + id Int @id + email String @unique + name String? + isActive Boolean @default(true) + + @@index([email], where: "isActive = true") + @@unique([name], where: "name IS NOT NULL") +} diff --git a/psl/psl/tests/validation/preview_features/partial_indexes/sqlite_unsupported.prisma b/psl/psl/tests/validation/preview_features/partial_indexes/sqlite_unsupported.prisma new file mode 100644 index 000000000000..2bd5dd7b68b8 --- /dev/null +++ b/psl/psl/tests/validation/preview_features/partial_indexes/sqlite_unsupported.prisma @@ -0,0 +1,23 @@ +generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +datasource db { + provider = "sqlite" + url = env("DATABASE_URL") +} + +model User { + id Int @id + email String @unique + isActive Boolean @default(true) + + @@index([email], where: "isActive = true") +} +// error: Error parsing attribute "@@index": Partial indexes are only supported on PostgreSQL and CockroachDB. Your connector is `sqlite`. +// --> schema.prisma:16 +//  |  +// 15 |  +// 16 |  @@index([email], where: "isActive = true") +//  |  diff --git a/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/renderer.rs b/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/renderer.rs index 28b8c3d7f448..f19c12a91b39 100644 --- a/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/renderer.rs +++ b/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/renderer.rs @@ -391,6 +391,7 @@ impl SqlRenderer for PostgresRenderer { operator_class: pg_ext.get_opclass(c.id).map(|c| c.kind.as_ref().into()), }) .collect(), + where_clause: pg_ext.get_partial_index_where_clause(index.id).map(|s| s.as_str()), } .to_string() } diff --git a/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/schema_calculator.rs b/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/schema_calculator.rs index 97bfcd9f2b1a..514ce6adee82 100644 --- a/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/schema_calculator.rs +++ b/schema-engine/connectors/sql-schema-connector/src/flavour/postgres/schema_calculator.rs @@ -137,6 +137,13 @@ impl SqlSchemaCalculatorFlavour for PostgresSchemaCalculatorFlavour { postgres_ext.opclasses.push((field_id, opclass)); } } + + // Add WHERE clause for partial indexes + if let Some(where_clause) = index.where_clause() { + postgres_ext + .partial_indexes + .insert(sql_index.id, where_clause.to_string()); + } } // Add sequences for the fields with a default sequence in the model. diff --git a/schema-engine/connectors/sql-schema-connector/src/introspection/introspection_pair/index.rs b/schema-engine/connectors/sql-schema-connector/src/introspection/introspection_pair/index.rs index 988a3cc06275..5894a9b44b6e 100644 --- a/schema-engine/connectors/sql-schema-connector/src/introspection/introspection_pair/index.rs +++ b/schema-engine/connectors/sql-schema-connector/src/introspection/introspection_pair/index.rs @@ -119,6 +119,24 @@ impl<'a> IndexPair<'a> { } } + /// The WHERE clause for partial indexes, specific to PostgreSQL and CockroachDB. + pub(crate) fn where_clause(self) -> Option<&'a str> { + if !self.context.sql_family().is_postgres() { + return None; + } + + match (self.next, self.previous) { + // Index is defined in a table to the database. + (Some(next), _) => { + let data: &PostgresSchemaExt = self.context.sql_schema.downcast_connector_data(); + data.get_partial_index_where_clause(next.id).map(|s| s.as_str()) + } + // For views, we copy whatever is written in PSL. + (None, Some(prev)) => prev.where_clause(), + _ => None, + } + } + /// The fields that are defining the index. pub(crate) fn fields(self) -> Box> + 'a> { match (self.next, self.previous) { diff --git a/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/configuration.rs b/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/configuration.rs index 1043f5a66ac0..15310c832a0a 100644 --- a/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/configuration.rs +++ b/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/configuration.rs @@ -1,8 +1,8 @@ //! Rendering of the datasource and generator parts of the PSL. use datamodel_renderer as render; -use psl::ValidatedSchema; -use sql_schema_describer::SqlSchema; +use psl::{PreviewFeature, ValidatedSchema}; +use sql_schema_describer::{SqlSchema, postgres::PostgresSchemaExt}; /// Render a configuration block. pub(super) fn render<'a>( @@ -25,11 +25,27 @@ pub(super) fn render<'a>( for prev_gen in &previous_schema.configuration.generators { let prev_gen_file_name = previous_schema.db.file_name(prev_gen.span.file_id); - output.push_generator( - prev_gen_file_name.to_owned(), - render::configuration::Generator::from_psl(prev_gen), - ); + let mut generator = render::configuration::Generator::from_psl(prev_gen); + + // Add partialIndexes preview feature if partial indexes are detected and not already present + if has_partial_indexes(schema) + && (prev_ds.active_connector.is_provider("postgresql") + || prev_ds.active_connector.is_provider("cockroachdb")) + && !prev_gen + .preview_features + .is_some_and(|features| features.contains(PreviewFeature::PartialIndexes)) + { + generator.push_preview_feature(PreviewFeature::PartialIndexes); + } + + output.push_generator(prev_gen_file_name.to_owned(), generator); } output } + +/// Check if the schema contains any partial indexes. +fn has_partial_indexes(schema: &SqlSchema) -> bool { + let pg_ext: &PostgresSchemaExt = schema.downcast_connector_data(); + !pg_ext.partial_indexes.is_empty() +} diff --git a/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/indexes.rs b/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/indexes.rs index 35894ca0fde8..ffdca3421ba7 100644 --- a/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/indexes.rs +++ b/schema-engine/connectors/sql-schema-connector/src/introspection/rendering/indexes.rs @@ -52,5 +52,9 @@ pub(super) fn render(index: IndexPair<'_>) -> renderer::IndexDefinition<'_> { definition.index_type(algo); } + if let Some(where_clause) = index.where_clause() { + definition.where_clause(where_clause); + } + definition } diff --git a/schema-engine/datamodel-renderer/src/datamodel/index.rs b/schema-engine/datamodel-renderer/src/datamodel/index.rs index ad974ca9b793..5eabc492db2d 100644 --- a/schema-engine/datamodel-renderer/src/datamodel/index.rs +++ b/schema-engine/datamodel-renderer/src/datamodel/index.rs @@ -54,6 +54,11 @@ impl<'a> IndexDefinition<'a> { .push_param(("type", Constant::new_no_validate(index_type.into()))); } + /// Defines the `where` argument for partial indexes. + pub fn where_clause(&mut self, where_clause: impl Into>) { + self.0.push_param(("where", Text::new(where_clause))); + } + fn new(index_type: &'static str, fields: impl Iterator>) -> Self { let mut inner = Function::new(index_type); diff --git a/schema-engine/sql-introspection-tests/tests/postgres/mod.rs b/schema-engine/sql-introspection-tests/tests/postgres/mod.rs index 40728ae2a41f..8baf51227f4c 100644 --- a/schema-engine/sql-introspection-tests/tests/postgres/mod.rs +++ b/schema-engine/sql-introspection-tests/tests/postgres/mod.rs @@ -3,6 +3,7 @@ mod constraints; mod extensions; mod gin; mod gist; +mod partial_indexes; mod spgist; use indoc::indoc; diff --git a/schema-engine/sql-introspection-tests/tests/postgres/partial_indexes.rs b/schema-engine/sql-introspection-tests/tests/postgres/partial_indexes.rs new file mode 100644 index 000000000000..a43a0bc158d6 --- /dev/null +++ b/schema-engine/sql-introspection-tests/tests/postgres/partial_indexes.rs @@ -0,0 +1,223 @@ +use expect_test::expect; +use indoc::indoc; +use quaint::prelude::Queryable; +use sql_introspection_tests::test_api::*; +use test_macros::test_connector; + +#[test_connector(tags(Postgres), exclude(CockroachDb))] +async fn partial_index_basic(api: &mut TestApi) -> TestResult { + let schema_name = api.schema_name(); + let create_table = format!( + "CREATE TABLE \"{schema_name}\".\"User\" (id SERIAL PRIMARY KEY, email VARCHAR(255), active BOOLEAN NOT NULL DEFAULT false)" + ); + let create_idx = + format!("CREATE INDEX \"User_email_idx\" ON \"{schema_name}\".\"User\" (email) WHERE email IS NOT NULL"); + + api.database().raw_cmd(&create_table).await?; + api.database().raw_cmd(&create_idx).await?; + + let expected = expect![[r#" + generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] + } + + datasource db { + provider = "postgresql" + url = "env(TEST_DATABASE_URL)" + } + + model User { + id Int @id @default(autoincrement()) + email String? @db.VarChar(255) + active Boolean @default(false) + + @@index([email], where: "(email IS NOT NULL)") + } + "#]]; + + let result = api.introspect().await?; + expected.assert_eq(&result); + + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb))] +async fn partial_unique_index(api: &mut TestApi) -> TestResult { + let schema_name = api.schema_name(); + let create_table = format!( + "CREATE TABLE \"{schema_name}\".\"Post\" (id SERIAL PRIMARY KEY, slug VARCHAR(255), published BOOLEAN NOT NULL DEFAULT false)" + ); + let create_idx = + format!("CREATE UNIQUE INDEX \"Post_slug_key\" ON \"{schema_name}\".\"Post\" (slug) WHERE published = true"); + + api.database().raw_cmd(&create_table).await?; + api.database().raw_cmd(&create_idx).await?; + + let expected = expect![[r#" + model Post { + id Int @id @default(autoincrement()) + slug String? @unique @db.VarChar(255) + published Boolean @default(false) + } + "#]]; + + let result = api.introspect_dml().await?; + expected.assert_eq(&result); + + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb))] +async fn compound_partial_index(api: &mut TestApi) -> TestResult { + let schema_name = api.schema_name(); + let create_table = format!( + "CREATE TABLE \"{schema_name}\".\"Order\" (id SERIAL PRIMARY KEY, user_id INT NOT NULL, status VARCHAR(20) NOT NULL, created_at TIMESTAMP)" + ); + let create_idx = format!( + "CREATE INDEX \"Order_user_status_idx\" ON \"{schema_name}\".\"Order\" (user_id, status) WHERE status IN ('pending', 'processing')" + ); + + api.database().raw_cmd(&create_table).await?; + api.database().raw_cmd(&create_idx).await?; + + let expected = expect![[r#" + model Order { + id Int @id @default(autoincrement()) + user_id Int + status String @db.VarChar(20) + created_at DateTime? @db.Timestamp(6) + + @@index([user_id, status], map: "Order_user_status_idx", where: "((status)::text = ANY ((ARRAY['pending'::character varying, 'processing'::character varying])::text[]))") + } + "#]]; + + let result = api.introspect_dml().await?; + expected.assert_eq(&result); + + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb))] +async fn multiple_partial_indexes_same_table(api: &mut TestApi) -> TestResult { + let schema_name = api.schema_name(); + let create_table = format!( + "CREATE TABLE \"{schema_name}\".\"Product\" (id SERIAL PRIMARY KEY, name VARCHAR(255), price DECIMAL(10,2), active BOOLEAN DEFAULT true, category_id INT)" + ); + let create_idx1 = + format!("CREATE INDEX \"Product_active_idx\" ON \"{schema_name}\".\"Product\" (name) WHERE active = true"); + let create_idx2 = + format!("CREATE INDEX \"Product_expensive_idx\" ON \"{schema_name}\".\"Product\" (price) WHERE price > 100.00"); + + api.database().raw_cmd(&create_table).await?; + api.database().raw_cmd(&create_idx1).await?; + api.database().raw_cmd(&create_idx2).await?; + + let expected = expect![[r#" + model Product { + id Int @id @default(autoincrement()) + name String? @db.VarChar(255) + price Decimal? @db.Decimal(10, 2) + active Boolean? @default(true) + category_id Int? + + @@index([name], map: "Product_active_idx", where: "(active = true)") + @@index([price], map: "Product_expensive_idx", where: "(price > 100.00)") + } + "#]]; + + let result = api.introspect_dml().await?; + expected.assert_eq(&result); + + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb))] +async fn partial_index_with_gin_type(api: &mut TestApi) -> TestResult { + let schema_name = api.schema_name(); + let create_table = format!( + "CREATE TABLE \"{schema_name}\".\"Document\" (id SERIAL PRIMARY KEY, tags TEXT[], published BOOLEAN DEFAULT false)" + ); + let create_idx = format!( + "CREATE INDEX \"Document_tags_idx\" ON \"{schema_name}\".\"Document\" USING GIN (tags) WHERE published = true" + ); + + api.database().raw_cmd(&create_table).await?; + api.database().raw_cmd(&create_idx).await?; + + let expected = expect![[r#" + model Document { + id Int @id @default(autoincrement()) + tags String[] + published Boolean? @default(false) + + @@index([tags], type: Gin, where: "(published = true)") + } + "#]]; + + let result = api.introspect_dml().await?; + expected.assert_eq(&result); + + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb), preview_features("partialIndexes"))] +async fn re_introspect_partial_index(api: &mut TestApi) -> TestResult { + let schema_name = api.schema_name(); + let create_table = format!( + "CREATE TABLE \"{schema_name}\".\"Task\" (id SERIAL PRIMARY KEY, title VARCHAR(255), completed BOOLEAN DEFAULT false)" + ); + let create_idx = + format!("CREATE INDEX \"Task_title_idx\" ON \"{schema_name}\".\"Task\" (title) WHERE completed = false"); + + api.database().raw_cmd(&create_table).await?; + api.database().raw_cmd(&create_idx).await?; + + let expected = expect![[r#" + generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] + } + + datasource db { + provider = "postgresql" + url = "env(TEST_DATABASE_URL)" + } + + model Task { + id Int @id @default(autoincrement()) + title String? @db.VarChar(255) + completed Boolean? @default(false) + + @@index([title], where: "(completed = false)") + } + "#]]; + + let result = api.introspect().await?; + expected.assert_eq(&result); + + // Test re-introspection to ensure schema stability + let input = indoc! {r#" + model Task { + id Int @id @default(autoincrement()) + title String? @db.VarChar(255) + completed Boolean? @default(false) + + @@index([title], where: "(completed = false)") + } + "#}; + + let expectation = expect![[r#" + model Task { + id Int @id @default(autoincrement()) + title String? @db.VarChar(255) + completed Boolean? @default(false) + + @@index([title], where: "(completed = false)") + } + "#]]; + + api.expect_re_introspected_datamodel(input, expectation).await; + + Ok(()) +} diff --git a/schema-engine/sql-introspection-tests/tests/re_introspection/postgresql.rs b/schema-engine/sql-introspection-tests/tests/re_introspection/postgresql.rs index eb33cf7d166a..f9ba6734c46f 100644 --- a/schema-engine/sql-introspection-tests/tests/re_introspection/postgresql.rs +++ b/schema-engine/sql-introspection-tests/tests/re_introspection/postgresql.rs @@ -282,3 +282,244 @@ async fn re_introspecting_uuid_default_on_uuid_typed_pk_field(api: &mut TestApi) api.expect_re_introspected_datamodel(prisma_schema, expected).await; Ok(()) } + +#[test_connector(tags(Postgres), exclude(CockroachDb), preview_features("partialIndexes"))] +async fn re_introspecting_partial_indexes_basic(api: &mut TestApi) -> TestResult { + let setup = indoc! {r#" + CREATE TABLE "User" ( + id SERIAL PRIMARY KEY, + email VARCHAR(255), + active BOOLEAN NOT NULL DEFAULT false + ); + + CREATE INDEX "User_email_idx" ON "User" (email) WHERE email IS NOT NULL; + "#}; + + api.raw_cmd(setup).await; + + let input_dm = indoc! {r#" + model User { + id Int @id @default(autoincrement()) + email String? @db.VarChar(255) + active Boolean @default(false) + + @@index([email], where: "email IS NOT NULL") + } + "#}; + + let expectation = expect![[r#" + model User { + id Int @id @default(autoincrement()) + email String? @db.VarChar(255) + active Boolean @default(false) + + @@index([email], where: "(email IS NOT NULL)") + } + "#]]; + + api.expect_re_introspected_datamodel(input_dm, expectation).await; + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb), preview_features("partialIndexes"))] +async fn re_introspecting_partial_unique_constraints(api: &mut TestApi) -> TestResult { + let setup = indoc! {r#" + CREATE TABLE "Post" ( + id SERIAL PRIMARY KEY, + slug VARCHAR(255), + published BOOLEAN NOT NULL DEFAULT false + ); + + CREATE UNIQUE INDEX "Post_slug_key" ON "Post" (slug) WHERE published = true; + "#}; + + api.raw_cmd(setup).await; + + let input_dm = indoc! {r#" + model Post { + id Int @id @default(autoincrement()) + slug String? @db.VarChar(255) + published Boolean @default(false) + + @@unique([slug], where: "published = true") + } + "#}; + + let expectation = expect![[r#" + model Post { + id Int @id @default(autoincrement()) + slug String? @unique @db.VarChar(255) + published Boolean @default(false) + } + "#]]; + + api.expect_re_introspected_datamodel(input_dm, expectation).await; + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb), preview_features("partialIndexes"))] +async fn re_introspecting_compound_partial_indexes(api: &mut TestApi) -> TestResult { + let setup = indoc! {r#" + CREATE TABLE "Order" ( + id SERIAL PRIMARY KEY, + user_id INT NOT NULL, + status VARCHAR(20) NOT NULL, + created_at TIMESTAMP + ); + + CREATE INDEX "Order_user_status_idx" ON "Order" (user_id, status) WHERE status IN ('pending', 'processing'); + "#}; + + api.raw_cmd(setup).await; + + let input_dm = indoc! {r#" + model Order { + id Int @id @default(autoincrement()) + user_id Int + status String @db.VarChar(20) + created_at DateTime? @db.Timestamp(6) + + @@index([user_id, status], where: "status IN ('pending', 'processing')") + } + "#}; + + let expectation = expect![[r#" + model Order { + id Int @id @default(autoincrement()) + user_id Int + status String @db.VarChar(20) + created_at DateTime? @db.Timestamp(6) + + @@index([user_id, status], map: "Order_user_status_idx", where: "((status)::text = ANY ((ARRAY['pending'::character varying, 'processing'::character varying])::text[]))") + } + "#]]; + + api.expect_re_introspected_datamodel(input_dm, expectation).await; + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb), preview_features("partialIndexes"))] +async fn re_introspecting_partial_indexes_with_custom_names(api: &mut TestApi) -> TestResult { + let setup = indoc! {r#" + CREATE TABLE "Product" ( + id SERIAL PRIMARY KEY, + name VARCHAR(255), + price DECIMAL(10,2), + active BOOLEAN DEFAULT true + ); + + CREATE INDEX "Product.custom@name" ON "Product" (name) WHERE active = true; + "#}; + + api.raw_cmd(setup).await; + + let input_dm = indoc! {r#" + model Product { + id Int @id @default(autoincrement()) + name String? @db.VarChar(255) + price Decimal? @db.Decimal(10, 2) + active Boolean? @default(true) + + @@index([name], map: "Product.custom@name", where: "active = true") + } + "#}; + + let expectation = expect![[r#" + model Product { + id Int @id @default(autoincrement()) + name String? @db.VarChar(255) + price Decimal? @db.Decimal(10, 2) + active Boolean? @default(true) + + @@index([name], map: "Product.custom@name", where: "(active = true)") + } + "#]]; + + api.expect_re_introspected_datamodel(input_dm, expectation).await; + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb), preview_features("partialIndexes"))] +async fn re_introspecting_partial_indexes_with_gin_algorithm(api: &mut TestApi) -> TestResult { + let setup = indoc! {r#" + CREATE TABLE "Document" ( + id SERIAL PRIMARY KEY, + tags TEXT[], + published BOOLEAN DEFAULT false + ); + + CREATE INDEX "Document_tags_idx" ON "Document" USING GIN (tags) WHERE published = true; + "#}; + + api.raw_cmd(setup).await; + + let input_dm = indoc! {r#" + model Document { + id Int @id @default(autoincrement()) + tags String[] + published Boolean? @default(false) + + @@index([tags], type: Gin, where: "published = true") + } + "#}; + + let expectation = expect![[r#" + model Document { + id Int @id @default(autoincrement()) + tags String[] + published Boolean? @default(false) + + @@index([tags], type: Gin, where: "(published = true)") + } + "#]]; + + api.expect_re_introspected_datamodel(input_dm, expectation).await; + Ok(()) +} + +#[test_connector(tags(Postgres), exclude(CockroachDb), preview_features("partialIndexes"))] +async fn re_introspecting_multiple_partial_indexes_same_table(api: &mut TestApi) -> TestResult { + let setup = indoc! {r#" + CREATE TABLE "Task" ( + id SERIAL PRIMARY KEY, + title VARCHAR(255), + priority INT, + completed BOOLEAN DEFAULT false, + archived BOOLEAN DEFAULT false + ); + + CREATE INDEX "Task_title_idx" ON "Task" (title) WHERE completed = false; + CREATE INDEX "Task_priority_idx" ON "Task" (priority) WHERE priority > 3 AND archived = false; + "#}; + + api.raw_cmd(setup).await; + + let input_dm = indoc! {r#" + model Task { + id Int @id @default(autoincrement()) + title String? @db.VarChar(255) + priority Int? + completed Boolean? @default(false) + archived Boolean? @default(false) + + @@index([title], where: "completed = false") + @@index([priority], where: "priority > 3 AND archived = false") + } + "#}; + + let expectation = expect![[r#" + model Task { + id Int @id @default(autoincrement()) + title String? @db.VarChar(255) + priority Int? + completed Boolean? @default(false) + archived Boolean? @default(false) + + @@index([title], where: "(completed = false)") + @@index([priority], where: "((priority > 3) AND (archived = false))") + } + "#]]; + + api.expect_re_introspected_datamodel(input_dm, expectation).await; + Ok(()) +} diff --git a/schema-engine/sql-introspection-tests/tests/tables/mod.rs b/schema-engine/sql-introspection-tests/tests/tables/mod.rs index 3fc69cdf9c51..683bbf0ba07c 100644 --- a/schema-engine/sql-introspection-tests/tests/tables/mod.rs +++ b/schema-engine/sql-introspection-tests/tests/tables/mod.rs @@ -590,36 +590,43 @@ async fn a_table_with_an_index_that_contains_expressions_should_be_ignored(api: } // MySQL doesn't have partial indices. +// This test validates that partial indexes are detected and the partialIndexes preview feature is added, +// even if field-level partial unique indexes are simplified to regular field-level unique indexes #[test_connector(exclude(Mysql, CockroachDb))] -async fn a_table_with_partial_indexes_should_ignore_them(api: &mut TestApi) -> TestResult { - api.barrel() - .execute(move |migration| { - migration.create_table("pages", move |t| { - t.add_column("id", types::integer().increments(true)); - t.add_column("staticId", types::integer().nullable(false)); - t.add_column("latest", types::integer().nullable(false)); - t.add_column("other", types::integer().nullable(false)); - t.add_index("full", types::index(vec!["other"]).unique(true)); - t.add_partial_index("partial", types::index(vec!["staticId"]).unique(true), "latest = 1"); +async fn a_table_with_partial_indexes_should_include_them(api: &mut TestApi) -> TestResult { + let schema_name = api.schema_name(); + let create_table = format!( + "CREATE TABLE \"{schema_name}\".\"pages\" (id SERIAL PRIMARY KEY, \"staticId\" INTEGER NOT NULL, latest INTEGER NOT NULL, other INTEGER NOT NULL)" + ); + let create_partial_idx = + format!("CREATE UNIQUE INDEX \"partial\" ON \"{schema_name}\".\"pages\" (\"staticId\") WHERE latest = 1"); + let create_full_idx = format!("CREATE UNIQUE INDEX \"full\" ON \"{schema_name}\".\"pages\" (other)"); + + api.database().raw_cmd(&create_table).await?; + api.database().raw_cmd(&create_partial_idx).await?; + api.database().raw_cmd(&create_full_idx).await?; + + // Note: Introspection detects partial indexes and adds the partialIndexes preview feature, + // but field-level partial unique indexes are simplified to regular unique indexes + api.expect_datamodel(&expect![[r#" + generator client { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] + } - t.add_constraint("pages_pkey", types::primary_constraint(vec!["id"])); - }); - }) - .await?; + datasource db { + provider = "postgresql" + url = "env(TEST_DATABASE_URL)" + } - let dm = indoc! { - r#" model pages { - id Int @id @default(autoincrement()) - staticId Int - latest Int - other Int @unique(map: "full") + id Int @id @default(autoincrement()) + staticId Int @unique(map: "partial") + latest Int + other Int @unique(map: "full") } - "# - }; - - let result = api.introspect().await?; - api.assert_eq_datamodels(dm, &result); + "#]]) + .await; Ok(()) } diff --git a/schema-engine/sql-introspection-tests/tests/tables/postgres.rs b/schema-engine/sql-introspection-tests/tests/tables/postgres.rs index 3bd127bf83ae..39f66a6c951e 100644 --- a/schema-engine/sql-introspection-tests/tests/tables/postgres.rs +++ b/schema-engine/sql-introspection-tests/tests/tables/postgres.rs @@ -153,32 +153,6 @@ async fn a_table_with_a_hash_index(api: &mut TestApi) -> TestResult { Ok(()) } -#[test_connector(tags(Postgres))] -async fn ignoring_of_partial_indices(api: &mut TestApi) -> TestResult { - let setup = indoc! {r#" - CREATE TABLE "A" ( - id INTEGER NOT NULL, - a INTEGER, - CONSTRAINT A_pkey PRIMARY KEY (id) - ); - - CREATE INDEX "A_a_idx" ON "A" Using Btree (a) Where (a is not null); - "#}; - - api.raw_cmd(setup).await; - - let expectation = expect![[r#" - model A { - id Int @id(map: "a_pkey") - a Int? - } - "#]]; - - expectation.assert_eq(&api.introspect_dml().await?); - - Ok(()) -} - #[test_connector(tags(Postgres))] async fn introspecting_now_functions(api: &mut TestApi) -> TestResult { let setup = indoc! {r#" diff --git a/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_basic.prisma b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_basic.prisma new file mode 100644 index 000000000000..f64e466aca31 --- /dev/null +++ b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_basic.prisma @@ -0,0 +1,47 @@ +// tags=postgres +// exclude=cockroachdb + +datasource testds { + provider = "postgresql" + url = env("TEST_DATABASE_URL") +} + +generator js { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +model User { + id Int @id @default(autoincrement()) + email String? @testds.VarChar(255) + isActive Boolean @default(false) + + @@index([email], where: "email IS NOT NULL") +} + +// -- CreateTable +// CREATE TABLE "User" ( +// "id" SERIAL NOT NULL, +// "email" VARCHAR(255), +// "isActive" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "User_pkey" PRIMARY KEY ("id") +// ); + +// -- CreateIndex +// CREATE INDEX "User_email_idx" ON "User"("email") WHERE email IS NOT NULL; +// Expected Migration: +// -- CreateSchema +// CREATE SCHEMA IF NOT EXISTS "public"; +// +// -- CreateTable +// CREATE TABLE "public"."User" ( +// "id" SERIAL NOT NULL, +// "email" VARCHAR(255), +// "isActive" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "User_pkey" PRIMARY KEY ("id") +// ); +// +// -- CreateIndex +// CREATE INDEX "User_email_idx" ON "public"."User"("email") WHERE email IS NOT NULL; diff --git a/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_compound.prisma b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_compound.prisma new file mode 100644 index 000000000000..79d28bd0f6f7 --- /dev/null +++ b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_compound.prisma @@ -0,0 +1,50 @@ +// tags=postgres +// exclude=cockroachdb + +datasource testds { + provider = "postgresql" + url = env("TEST_DATABASE_URL") +} + +generator js { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +model Order { + id Int @id @default(autoincrement()) + userId Int + status String @testds.VarChar(20) + createdAt DateTime? @testds.Timestamp(6) + + @@index([userId, status], where: "status IN ('pending', 'processing')") +} + +// -- CreateTable +// CREATE TABLE "Order" ( +// "id" SERIAL NOT NULL, +// "userId" INTEGER NOT NULL, +// "status" VARCHAR(20) NOT NULL, +// "createdAt" TIMESTAMP(6), +// +// CONSTRAINT "Order_pkey" PRIMARY KEY ("id") +// ); + +// -- CreateIndex +// CREATE INDEX "Order_userId_status_idx" ON "Order"("userId", "status") WHERE status IN ('pending', 'processing'); +// Expected Migration: +// -- CreateSchema +// CREATE SCHEMA IF NOT EXISTS "public"; +// +// -- CreateTable +// CREATE TABLE "public"."Order" ( +// "id" SERIAL NOT NULL, +// "userId" INTEGER NOT NULL, +// "status" VARCHAR(20) NOT NULL, +// "createdAt" TIMESTAMP(6), +// +// CONSTRAINT "Order_pkey" PRIMARY KEY ("id") +// ); +// +// -- CreateIndex +// CREATE INDEX "Order_userId_status_idx" ON "public"."Order"("userId", "status") WHERE status IN ('pending', 'processing'); diff --git a/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_custom_name.prisma b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_custom_name.prisma new file mode 100644 index 000000000000..9d87fcf50771 --- /dev/null +++ b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_custom_name.prisma @@ -0,0 +1,47 @@ +// tags=postgres +// exclude=cockroachdb + +datasource testds { + provider = "postgresql" + url = env("TEST_DATABASE_URL") +} + +generator js { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +model Product { + id Int @id @default(autoincrement()) + name String? @testds.VarChar(255) + active Boolean @default(true) + + @@index([name], map: "idx_active_products", where: "active = true") +} + +// -- CreateTable +// CREATE TABLE "Product" ( +// "id" SERIAL NOT NULL, +// "name" VARCHAR(255), +// "active" BOOLEAN NOT NULL DEFAULT true, +// +// CONSTRAINT "Product_pkey" PRIMARY KEY ("id") +// ); + +// -- CreateIndex +// CREATE INDEX "idx_active_products" ON "Product"("name") WHERE active = true; +// Expected Migration: +// -- CreateSchema +// CREATE SCHEMA IF NOT EXISTS "public"; +// +// -- CreateTable +// CREATE TABLE "public"."Product" ( +// "id" SERIAL NOT NULL, +// "name" VARCHAR(255), +// "active" BOOLEAN NOT NULL DEFAULT true, +// +// CONSTRAINT "Product_pkey" PRIMARY KEY ("id") +// ); +// +// -- CreateIndex +// CREATE INDEX "idx_active_products" ON "public"."Product"("name") WHERE active = true; diff --git a/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_multiple.prisma b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_multiple.prisma new file mode 100644 index 000000000000..b7f184e9d94c --- /dev/null +++ b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_multiple.prisma @@ -0,0 +1,60 @@ +// tags=postgres +// exclude=cockroachdb + +datasource testds { + provider = "postgresql" + url = env("TEST_DATABASE_URL") +} + +generator js { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +model Task { + id Int @id @default(autoincrement()) + title String? @testds.VarChar(255) + priority Int? + completed Boolean @default(false) + archived Boolean @default(false) + + @@index([title], where: "completed = false") + @@index([priority], where: "priority > 3 AND archived = false") +} + +// -- CreateTable +// CREATE TABLE "Task" ( +// "id" SERIAL NOT NULL, +// "title" VARCHAR(255), +// "priority" INTEGER, +// "completed" BOOLEAN NOT NULL DEFAULT false, +// "archived" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "Task_pkey" PRIMARY KEY ("id") +// ); + +// -- CreateIndex +// CREATE INDEX "Task_title_idx" ON "Task"("title") WHERE completed = false; + +// -- CreateIndex +// CREATE INDEX "Task_priority_idx" ON "Task"("priority") WHERE priority > 3 AND archived = false; +// Expected Migration: +// -- CreateSchema +// CREATE SCHEMA IF NOT EXISTS "public"; +// +// -- CreateTable +// CREATE TABLE "public"."Task" ( +// "id" SERIAL NOT NULL, +// "title" VARCHAR(255), +// "priority" INTEGER, +// "completed" BOOLEAN NOT NULL DEFAULT false, +// "archived" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "Task_pkey" PRIMARY KEY ("id") +// ); +// +// -- CreateIndex +// CREATE INDEX "Task_title_idx" ON "public"."Task"("title") WHERE completed = false; +// +// -- CreateIndex +// CREATE INDEX "Task_priority_idx" ON "public"."Task"("priority") WHERE priority > 3 AND archived = false; diff --git a/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_unique.prisma b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_unique.prisma new file mode 100644 index 000000000000..1ec53ccde6d0 --- /dev/null +++ b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_unique.prisma @@ -0,0 +1,47 @@ +// tags=postgres +// exclude=cockroachdb + +datasource testds { + provider = "postgresql" + url = env("TEST_DATABASE_URL") +} + +generator js { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +model Post { + id Int @id @default(autoincrement()) + slug String? @testds.VarChar(255) + published Boolean @default(false) + + @@unique([slug], where: "published = true") +} + +// -- CreateTable +// CREATE TABLE "Post" ( +// "id" SERIAL NOT NULL, +// "slug" VARCHAR(255), +// "published" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "Post_pkey" PRIMARY KEY ("id") +// ); + +// -- CreateIndex +// CREATE UNIQUE INDEX "Post_slug_key" ON "Post"("slug") WHERE published = true; +// Expected Migration: +// -- CreateSchema +// CREATE SCHEMA IF NOT EXISTS "public"; +// +// -- CreateTable +// CREATE TABLE "public"."Post" ( +// "id" SERIAL NOT NULL, +// "slug" VARCHAR(255), +// "published" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "Post_pkey" PRIMARY KEY ("id") +// ); +// +// -- CreateIndex +// CREATE UNIQUE INDEX "Post_slug_key" ON "public"."Post"("slug") WHERE published = true; diff --git a/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_with_gin.prisma b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_with_gin.prisma new file mode 100644 index 000000000000..233adbbd6f10 --- /dev/null +++ b/schema-engine/sql-migration-tests/tests/single_migration_tests/postgres/partial_indexes_with_gin.prisma @@ -0,0 +1,47 @@ +// tags=postgres +// exclude=cockroachdb + +datasource testds { + provider = "postgresql" + url = env("TEST_DATABASE_URL") +} + +generator js { + provider = "prisma-client-js" + previewFeatures = ["partialIndexes"] +} + +model Document { + id Int @id @default(autoincrement()) + tags String[] + published Boolean @default(false) + + @@index([tags], type: Gin, where: "published = true") +} + +// -- CreateTable +// CREATE TABLE "Document" ( +// "id" SERIAL NOT NULL, +// "tags" TEXT[], +// "published" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "Document_pkey" PRIMARY KEY ("id") +// ); + +// -- CreateIndex +// CREATE INDEX "Document_tags_idx" ON "Document" USING GIN ("tags") WHERE published = true; +// Expected Migration: +// -- CreateSchema +// CREATE SCHEMA IF NOT EXISTS "public"; +// +// -- CreateTable +// CREATE TABLE "public"."Document" ( +// "id" SERIAL NOT NULL, +// "tags" TEXT[], +// "published" BOOLEAN NOT NULL DEFAULT false, +// +// CONSTRAINT "Document_pkey" PRIMARY KEY ("id") +// ); +// +// -- CreateIndex +// CREATE INDEX "Document_tags_idx" ON "public"."Document" USING GIN ("tags") WHERE published = true; diff --git a/schema-engine/sql-schema-describer/src/postgres.rs b/schema-engine/sql-schema-describer/src/postgres.rs index d03f9aa019ae..98d0ddb35746 100644 --- a/schema-engine/sql-schema-describer/src/postgres.rs +++ b/schema-engine/sql-schema-describer/src/postgres.rs @@ -153,6 +153,8 @@ pub struct PostgresSchemaExt { pub constraint_options: HashMap>, pub table_options: Vec>, pub exclude_constraints: Vec<(TableId, String)>, + /// WHERE clauses for partial indexes + pub partial_indexes: HashMap, /// The schema's sequences. pub sequences: Vec, /// The extensions included in the schema(s). @@ -251,6 +253,10 @@ impl PostgresSchemaExt { } } + pub fn get_partial_index_where_clause(&self, index_id: IndexId) -> Option<&String> { + self.partial_indexes.get(&index_id) + } + pub fn exclude_constraints(&self, table_id: TableId) -> impl ExactSizeIterator { let low = self.exclude_constraints.partition_point(|(id, _)| *id < table_id); let high = self.exclude_constraints[low..].partition_point(|(id, _)| *id <= table_id); @@ -1418,13 +1424,20 @@ fn index_from_row( if column_index == 0 { // new index! let index_id = if is_primary_key { - sql_schema.push_primary_key(table_id, index_name) + sql_schema.push_primary_key(table_id, index_name.clone()) } else if is_unique { - sql_schema.push_unique_constraint(table_id, index_name) + sql_schema.push_unique_constraint(table_id, index_name.clone()) } else { - sql_schema.push_index(table_id, index_name) + sql_schema.push_index(table_id, index_name.clone()) }; + // Store WHERE clause for partial indexes + if let Some(where_clause) = row.get_string("where_clause") { + if !where_clause.is_empty() { + pg_ext.partial_indexes.insert(index_id, where_clause); + } + } + if is_primary_key || is_unique { let mut constraint_options = BitFlags::empty(); diff --git a/schema-engine/sql-schema-describer/src/postgres/indexes_query.sql b/schema-engine/sql-schema-describer/src/postgres/indexes_query.sql index d408b38aab35..5ab7e9878b5a 100644 --- a/schema-engine/sql-schema-describer/src/postgres/indexes_query.sql +++ b/schema-engine/sql-schema-describer/src/postgres/indexes_query.sql @@ -4,14 +4,14 @@ WITH rawindex AS ( indexrelid, indisunique, indisprimary, + indpred, unnest(indkey) AS indkeyid, generate_subscripts(indkey, 1) AS indkeyidx, unnest(indclass) AS indclass, unnest(indoption) AS indoption FROM pg_index -- https://www.postgresql.org/docs/current/catalog-pg-index.html WHERE - indpred IS NULL -- filter out partial indexes - AND NOT indisexclusion -- filter out exclusion constraints + NOT indisexclusion -- filter out exclusion constraints ) SELECT schemainfo.nspname AS namespace, @@ -33,7 +33,8 @@ SELECT ELSE false END AS nulls_first, pc.condeferrable AS condeferrable, - pc.condeferred AS condeferred + pc.condeferred AS condeferred, + pg_get_expr(rawindex.indpred, rawindex.indrelid) AS where_clause FROM rawindex INNER JOIN pg_class AS tableinfo ON tableinfo.oid = rawindex.indrelid diff --git a/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests.rs b/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests.rs index f3f918e5f801..c9251e89c62c 100644 --- a/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests.rs +++ b/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests.rs @@ -1037,6 +1037,7 @@ fn all_postgres_column_types_must_work(api: TestApi) { {}, ], exclude_constraints: [], + partial_indexes: {}, sequences: [ Sequence { namespace_id: NamespaceId( @@ -1214,6 +1215,7 @@ fn postgres_sequences_must_work(api: TestApi) { constraint_options: {}, table_options: [], exclude_constraints: [], + partial_indexes: {}, sequences: [ Sequence { namespace_id: NamespaceId( @@ -1815,6 +1817,7 @@ fn extensions_are_described_correctly(api: TestApi) { constraint_options: {}, table_options: [], exclude_constraints: [], + partial_indexes: {}, sequences: [], extensions: [ DatabaseExtension { diff --git a/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests/cockroach_describer_tests.rs b/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests/cockroach_describer_tests.rs index 4b3ef1ad4c27..ad1390c448d3 100644 --- a/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests/cockroach_describer_tests.rs +++ b/schema-engine/sql-schema-describer/tests/describers/postgres_describer_tests/cockroach_describer_tests.rs @@ -530,6 +530,7 @@ fn cockroachdb_22_2_sequences_must_work(api: TestApi) { constraint_options: {}, table_options: [], exclude_constraints: [], + partial_indexes: {}, sequences: [ Sequence { namespace_id: NamespaceId(