From bc99ac7f61e7793ad06f625aac1938d47ddc4f54 Mon Sep 17 00:00:00 2001 From: Jay Lee Date: Wed, 11 Feb 2026 22:39:02 +0900 Subject: [PATCH 1/6] feat(docs): add documentation for partial indexes (filtered indexes) support Add comprehensive documentation for the new `partialIndexes` preview feature, which enables `where` argument on `@@index`, `@@unique`, and `@unique` attributes for PostgreSQL, SQLite, SQL Server, and CockroachDB. Ref: prisma/prisma-engines#5749, prisma/prisma#6974 --- .../500-databases/800-sql-server/index.mdx | 2 + .../20-data-model/30-indexes.mdx | 163 ++++++++++++++++++ .../70-unsupported-database-features.mdx | 8 +- .../050-getting-started.mdx | 11 +- .../110-native-database-types.mdx | 2 +- .../80-unsupported-database-features.mdx | 19 +- .../90-development-and-production.mdx | 2 +- .../100-prisma-schema-reference.mdx | 48 ++++-- .../500-reference/350-database-features.mdx | 2 +- .../050-client-preview-features.mdx | 1 + 10 files changed, 229 insertions(+), 29 deletions(-) diff --git a/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx b/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx index 0180d4424b..61caedd435 100644 --- a/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx +++ b/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx @@ -254,6 +254,8 @@ Microsoft SQL Server [only allows one `NULL` value in a column that has a `UNIQU The standard way to get around this issue is to create a filtered unique index that excludes `NULL` values. This allows you to insert multiple `NULL` values. If you do not create an index in the database, you will get an error if you try to insert more than one `null` value into a column with Prisma Client. +With the [`partialIndexes` Preview feature](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where), you can now define filtered indexes directly in your Prisma schema using the `where` argument on `@@unique` or `@@index`. + _However_, creating an index makes it impossible to use `license_number` as a foreign key in the database (or a relation scalar field in corresponding Prisma Schema) ### Raw query considerations diff --git a/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx b/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx index 9cbe28a016..c735d0d7d6 100644 --- a/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx +++ b/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx @@ -46,6 +46,11 @@ You can configure indexes, unique constraints, and primary key constraints with - Available on the `@id`, `@@id`, `@unique`, `@@unique` and `@@index` attributes - Supported in all databases +- The [`where` argument](#configuring-partial-indexes-with-where) allows you to define partial indexes that only include rows matching a specified condition + - Available on the `@unique`, `@@unique` and `@@index` attributes + - PostgreSQL, SQLite, SQL Server, and CockroachDB + - Requires the `partialIndexes` Preview feature + See the linked sections for details of which version each feature was first introduced in. ### Configuring the length of indexes with `length` (MySQL) @@ -510,6 +515,164 @@ model Post { } ``` +### Configuring partial indexes with `where` + +The `where` argument allows you to define [partial indexes](https://www.postgresql.org/docs/current/indexes-partial.html) (also known as filtered indexes). A partial index only includes rows that match a specified condition, which reduces the index size and improves both write performance and query performance for the indexed subset of data. + +The `where` argument is available on the `@unique`, `@@unique` and `@@index` attributes. It requires the `partialIndexes` Preview feature. + +:::note + +Partial indexes are supported on **PostgreSQL**, **SQLite**, **SQL Server**, and **CockroachDB**. They are **not** supported on MySQL. + +::: + +#### Enabling the `partialIndexes` Preview feature + +To use partial indexes, add the `partialIndexes` feature flag to the `generator` block of your `schema.prisma` file: + +```prisma file=schema.prisma showLineNumbers +generator client { + provider = "prisma-client" + output = "./generated" + previewFeatures = ["partialIndexes"] +} +``` + +#### Raw SQL syntax with `raw()` + +You can define a partial index with a raw SQL predicate string using the `raw()` function. This approach supports any valid SQL `WHERE` expression that your database accepts: + +```prisma file=schema.prisma showLineNumbers +model User { + id Int @id + email String + status String + + @@unique([email], where: raw("status = 'active'")) + @@index([email], where: raw("deletedAt IS NULL")) +} +``` + +This generates SQL like: + + + + +```sql +CREATE UNIQUE INDEX "User_email_key" ON "User" ("email") WHERE (status = 'active'); +``` + + + + +```sql +CREATE UNIQUE INDEX "User_email_key" ON "User" ("email") WHERE status = 'active'; +``` + + + + +```sql +CREATE UNIQUE NONCLUSTERED INDEX [User_email_key] ON [dbo].[User]([email]) WHERE ([status]='active'); +``` + + + + +The `raw()` syntax can be used with any SQL expression your database supports, making it the most flexible option. + +#### Object literal syntax (type-safe alternative) + +You can also define partial indexes using an object literal syntax, which provides type-safety by validating field names and value types against your Prisma schema: + +```prisma file=schema.prisma showLineNumbers +model Post { + id Int @id + title String + published Boolean + + @@index([title], where: { published: true }) + @@unique([title], where: { published: true }) +} +``` + +The object literal syntax supports the following value types: + +| Value type | Example | Notes | +| ---------------- | ---------------------------------------- | ------------------------------------------------------ | +| `Boolean` | `{ active: true }`, `{ deleted: false }` | For `Boolean` fields | +| `String` | `{ status: "active" }` | For `String` and `DateTime` fields | +| `Number` | `{ priority: 1 }`, `{ score: 1.5 }` | For `Int`, `BigInt`, `Float`, and `Decimal` fields | +| `null` | `{ deletedAt: null }` | Translates to `IS NULL`. Works with any nullable field | +| `{ not: value }` | `{ deletedAt: { not: null } }` | Negation. Translates to `IS NOT NULL` or `!= value` | + +You can combine multiple conditions in a single object: + +```prisma file=schema.prisma showLineNumbers +model User { + id Int @id + email String + active Boolean + deletedAt DateTime? + + @@unique([email], where: { active: true, deletedAt: null }) +} +``` + +:::note + +The object literal syntax validates field types. For example, you cannot use a `Boolean` value for a `String` field. For fields with types that are not supported by the object syntax (such as `Unsupported` types), use `raw()` instead. + +::: + +#### Using `where` with other index arguments + +The `where` argument can be combined with other index arguments such as `name` and `map`: + +```prisma file=schema.prisma showLineNumbers +model User { + id Int @id + email String + status String + + @@unique([email], name: "email_active_unique", map: "idx_email_active", where: raw("status = 'active'")) +} +``` + +#### Database-specific behavior + +| Database | Migrations | Introspection | Notes | +| ----------- | ------------- | ------------- | ---------------------------------------------------------------------- | +| PostgreSQL | Full support | Full support | Full predicate support | +| SQLite | Full support | Full support | Full predicate support | +| SQL Server | Full support | Full support | Filtered indexes via `CREATE INDEX` | +| CockroachDB | Create only | Not supported | Cannot introspect predicate text; predicate modifications not detected | +| MySQL | Not supported | Not supported | Partial indexes are not supported by the database | + +:::warning + +**CockroachDB limitation**: CockroachDB supports creating partial indexes, but it cannot introspect the predicate text from existing indexes. This means that after initial creation, modifications to the `where` clause (adding, changing, or removing a predicate) will not be detected by Prisma Migrate. The differ skips predicate comparison for CockroachDB to prevent false-positive migrations. + +::: + +#### Introspection + +When you run `prisma db pull` on a database that contains partial indexes, Prisma ORM will: + +1. Automatically add `"partialIndexes"` to the `previewFeatures` list in your generator block +2. Represent the partial index predicate using the `raw()` syntax with the database's normalized form of the SQL expression + +For example, a PostgreSQL partial unique index on a single field will be introspected as: + +```prisma file=schema.prisma showLineNumbers +model User { + id Int @id + email String @unique(where: raw("(status = 'active'::text)")) + status String +} +``` + ### Upgrading from previous versions :::warning diff --git a/content/200-orm/100-prisma-schema/20-data-model/70-unsupported-database-features.mdx b/content/200-orm/100-prisma-schema/20-data-model/70-unsupported-database-features.mdx index cc27bd16c3..adba197268 100644 --- a/content/200-orm/100-prisma-schema/20-data-model/70-unsupported-database-features.mdx +++ b/content/200-orm/100-prisma-schema/20-data-model/70-unsupported-database-features.mdx @@ -103,4 +103,10 @@ The `prisma migrate dev` and `prisma db push` command will both create a `positi ## Unsupported database features -Some features, like SQL views or partial indexes, cannot be represented in the Prisma schema. If your project uses [Prisma Migrate](/orm/prisma-migrate), you must [include unsupported features as part of a migration](/orm/prisma-migrate/workflows/unsupported-database-features) . +Some features, like SQL views, cannot be represented in the Prisma schema. If your project uses [Prisma Migrate](/orm/prisma-migrate), you must [include unsupported features as part of a migration](/orm/prisma-migrate/workflows/unsupported-database-features) . + +:::tip + +Partial indexes are now supported in Prisma Schema Language via the `where` argument on `@@index`, `@@unique`, and `@unique`. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. + +::: diff --git a/content/200-orm/300-prisma-migrate/050-getting-started.mdx b/content/200-orm/300-prisma-migrate/050-getting-started.mdx index b78d99c41d..352be989b0 100644 --- a/content/200-orm/300-prisma-migrate/050-getting-started.mdx +++ b/content/200-orm/300-prisma-migrate/050-getting-started.mdx @@ -242,13 +242,18 @@ To include [unsupported database features](/orm/prisma-migrate/workflows/unsuppo 1. Open the `migration.sql` file generated in the [Create a baseline migration](#create-a-baseline-migration) section. 1. Modify the generated SQL. For example: - - If the changes are minor, you can append additional custom SQL to the generated migration. The following example creates a partial index: + - If the changes are minor, you can append additional custom SQL to the generated migration. The following example creates a stored procedure: ```sql /* Generated migration SQL */ --add-start - CREATE UNIQUE INDEX tests_success_constraint ON posts (subject, target) - WHERE success; + CREATE OR REPLACE FUNCTION notify_on_insert() + RETURNS TRIGGER AS $$ + BEGIN + PERFORM pg_notify('new_record', NEW.id::text); + RETURN NEW; + END; + $$ LANGUAGE plpgsql; --add-end ``` - If the changes are significant, it can be easier to replace the entire migration file with the result of a database dump ([`mysqldump`](https://dev.mysql.com/doc/refman/8.0/en/mysqldump.html), [`pg_dump`](https://www.postgresql.org/docs/12/app-pgdump.html)). When using `pg_dump` for this, you'll need to update the `search_path` as follows with this command: `SELECT pg_catalog.set_config('search_path', '', false);`; otherwise you'll run into the following error: `The underlying table for model '_prisma_migrations' does not exist.` diff --git a/content/200-orm/300-prisma-migrate/300-workflows/110-native-database-types.mdx b/content/200-orm/300-prisma-migrate/300-workflows/110-native-database-types.mdx index 81357ea4b3..ce27b01e80 100644 --- a/content/200-orm/300-prisma-migrate/300-workflows/110-native-database-types.mdx +++ b/content/200-orm/300-prisma-migrate/300-workflows/110-native-database-types.mdx @@ -97,7 +97,7 @@ For type mappings organized by database provider, see: ## Handling unsupported database features -Prisma Migrate cannot automatically create database features that have no equivalent in Prisma Schema Language (PSL). For example, there is currently no way to define a stored procedure or a partial index in PSL. However, there are ways to add unsupported features to your database with Prisma Migrate: +Prisma Migrate cannot automatically create database features that have no equivalent in Prisma Schema Language (PSL). For example, there is currently no way to define a stored procedure or a trigger in PSL. However, there are ways to add unsupported features to your database with Prisma Migrate: - [Handle unsupported field types](/orm/prisma-schema/data-model/unsupported-database-features#unsupported-field-types) (like `circle`) - [Handle unsupported features](/orm/prisma-schema/data-model/unsupported-database-features#unsupported-database-features), like stored procedures diff --git a/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx b/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx index 4e3fd00c03..e67864946f 100644 --- a/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx +++ b/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx @@ -12,12 +12,17 @@ Prisma Migrate uses the Prisma schema to determine what features to create in th - Stored procedures - Triggers - Views -- Partial indexes To add an unsupported feature to your database, you must [customize a migration](/orm/prisma-migrate/workflows/customizing-migrations) to include that feature before you apply it. :::tip +Partial indexes are now supported in Prisma Schema Language via the `where` argument on `@@index`, `@@unique`, and `@unique`. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. You no longer need to customize migrations for partial indexes. + +::: + +:::tip + The Prisma schema is able to represent [unsupported field types](/orm/prisma-schema/data-model/unsupported-database-features#unsupported-field-types) and [native database functions](/orm/prisma-migrate/workflows/native-database-functions). ::: @@ -41,12 +46,16 @@ To customize a migration to include an unsupported feature: npx prisma migrate dev --create-only ``` -1. Open the generated `migration.sql` file and add the unsupported feature - for example, a partial index: +1. Open the generated `migration.sql` file and add the unsupported feature - for example, a stored procedure: ```sql - CREATE UNIQUE INDEX tests_success_constraint - ON posts (subject, target) - WHERE success; + CREATE OR REPLACE FUNCTION notify_on_insert() + RETURNS TRIGGER AS $$ + BEGIN + PERFORM pg_notify('new_record', NEW.id::text); + RETURN NEW; + END; + $$ LANGUAGE plpgsql; ``` 1. Apply the migration: diff --git a/content/200-orm/300-prisma-migrate/300-workflows/90-development-and-production.mdx b/content/200-orm/300-prisma-migrate/300-workflows/90-development-and-production.mdx index 10049b806a..0bfe1822cb 100644 --- a/content/200-orm/300-prisma-migrate/300-workflows/90-development-and-production.mdx +++ b/content/200-orm/300-prisma-migrate/300-workflows/90-development-and-production.mdx @@ -72,7 +72,7 @@ Sometimes, you need to modify a migration **before applying it**. For example: - You want to introduce a significant refactor, such as changing blog post tags from a `String[]` to a `Tag[]` - You want to [rename a field](/orm/prisma-migrate/workflows/customizing-migrations#example-rename-a-field) (by default, Prisma Migrate will drop the existing field) - You want to [change the direction of a 1-1 relationship](/orm/prisma-migrate/workflows/customizing-migrations#example-change-the-direction-of-a-1-1-relation) -- You want to add features that cannot be represented in Prisma Schema Language - such as a partial index or a stored procedure. +- You want to add features that cannot be represented in Prisma Schema Language - such as a stored procedure or a trigger. The `--create-only` command allows you to create a migration without applying it: diff --git a/content/200-orm/500-reference/100-prisma-schema-reference.mdx b/content/200-orm/500-reference/100-prisma-schema-reference.mdx index 69a57bf89e..ccfa41aa16 100644 --- a/content/200-orm/500-reference/100-prisma-schema-reference.mdx +++ b/content/200-orm/500-reference/100-prisma-schema-reference.mdx @@ -2041,19 +2041,20 @@ Defines a unique constraint for this field. #### Arguments -| Name | Required | Type | Description | -| ----------- | -------- | --------- | ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | -| `map` | **No** | `String` | | -| `length` | **No** | `number` | Allows you to specify a maximum length for the subpart of the value to be indexed.

MySQL only. In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | -| `sort` | **No** | `String` | Allows you to specify in what order the entries of the constraint are stored in the database. The available options are `Asc` and `Desc`.

In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | -| `clustered` | **No** | `Boolean` | Defines whether the constraint is clustered or non-clustered. Defaults to `false`.

SQL Server only. In preview in versions 3.13.0 and later, and in general availability in versions 4.0.0 and later. | +| Name | Required | Type | Description | +| ----------- | -------- | ---------------------- | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | +| `map` | **No** | `String` | | +| `length` | **No** | `number` | Allows you to specify a maximum length for the subpart of the value to be indexed.

MySQL only. In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | +| `sort` | **No** | `String` | Allows you to specify in what order the entries of the constraint are stored in the database. The available options are `Asc` and `Desc`.

In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | +| `clustered` | **No** | `Boolean` | Defines whether the constraint is clustered or non-clustered. Defaults to `false`.

SQL Server only. In preview in versions 3.13.0 and later, and in general availability in versions 4.0.0 and later. | +| `where` | **No** | `function` or `object` | Defines a [partial index](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) that only includes rows matching the specified condition. Accepts `raw("SQL expression")` or an object literal like `{ field: value }`.

PostgreSQL, SQLite, SQL Server, and CockroachDB. Requires the `partialIndexes` Preview feature. | - ¹ Can be required by some of the index and field types. #### Signature ```prisma no-lines -@unique(map: String?, length: number?, sort: String?) +@unique(map: String?, length: number?, sort: String?, where: raw(String)?) ``` > **Note**: Before version 4.0.0, or 3.5.0 with the `extendedIndexes` Preview feature enabled, the signature was: @@ -2235,14 +2236,15 @@ Defines a compound [unique constraint](/orm/prisma-schema/data-model/models#defi #### Arguments -| Name | Required | Type | Description | -| ----------- | -------- | ------------------ | ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | -| `fields` | **Yes** | `FieldReference[]` | A list of field names - for example, `["firstname", "lastname"]`. Fields must be mandatory - see remarks. | -| `name` | **No** | `String` | The name of the unique combination of fields - defaults to `fieldName1_fieldName2_fieldName3` | -| `map` | **No** | `String` | | -| `length` | **No** | `number` | Allows you to specify a maximum length for the subpart of the value to be indexed.

MySQL only. In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | -| `sort` | **No** | `String` | Allows you to specify in what order the entries of the constraint are stored in the database. The available options are `Asc` and `Desc`.

In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | -| `clustered` | **No** | `Boolean` | Defines whether the constraint is clustered or non-clustered. Defaults to `false`.

SQL Server only. In preview in versions 3.13.0 and later, and in general availability in versions 4.0.0 and later. | +| Name | Required | Type | Description | +| ----------- | -------- | ---------------------- | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | +| `fields` | **Yes** | `FieldReference[]` | A list of field names - for example, `["firstname", "lastname"]`. Fields must be mandatory - see remarks. | +| `name` | **No** | `String` | The name of the unique combination of fields - defaults to `fieldName1_fieldName2_fieldName3` | +| `map` | **No** | `String` | | +| `length` | **No** | `number` | Allows you to specify a maximum length for the subpart of the value to be indexed.

MySQL only. In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | +| `sort` | **No** | `String` | Allows you to specify in what order the entries of the constraint are stored in the database. The available options are `Asc` and `Desc`.

In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | +| `clustered` | **No** | `Boolean` | Defines whether the constraint is clustered or non-clustered. Defaults to `false`.

SQL Server only. In preview in versions 3.13.0 and later, and in general availability in versions 4.0.0 and later. | +| `where` | **No** | `function` or `object` | Defines a [partial index](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) that only includes rows matching the specified condition. Accepts `raw("SQL expression")` or an object literal like `{ field: value }`.

PostgreSQL, SQLite, SQL Server, and CockroachDB. Requires the `partialIndexes` Preview feature. | The name of the `fields` argument on the `@@unique` attribute can be omitted: @@ -2261,6 +2263,12 @@ The `length` and `sort` arguments are added to the relevant field names: #### Signature +> ```prisma no-lines +> @@unique(_ fields: FieldReference[], name: String?, map: String?, where: raw(String)?) +> ``` + +> **Note**: Before the `partialIndexes` Preview feature, the signature was: +> > ```prisma no-lines > @@unique(_ fields: FieldReference[], name: String?, map: String?) > ``` @@ -2465,7 +2473,6 @@ Defines an index in the database. - There are some additional index configuration options that cannot be provided via the Prisma schema yet. These include: - PostgreSQL and CockroachDB: - Define index fields as expressions (e.g. `CREATE INDEX title ON public."Post"((lower(title)) text_ops);`) - - Define partial indexes with `WHERE` - Create indexes concurrently with `CONCURRENTLY` :::info @@ -2490,6 +2497,7 @@ While you cannot configure these option in your Prisma schema, you can still con | `clustered` | **No** | `Boolean` | Defines whether the index is clustered or non-clustered. Defaults to `false`.

SQL Server only. In preview in versions 3.5.0 and later, and in general availability in versions 4.0.0 and later. | | `type` | **No** | `identifier` | Allows you to specify an index access method. Defaults to `BTree`.

PostgreSQL and CockroachDB only. In preview with the `Hash` index access method in versions 3.6.0 and later, and with the `Gist`, `Gin`, `SpGist` and `Brin` methods added in 3.14.0. In general availability in versions 4.0.0 and later. | | `ops` | **No** | `identifier` or a `function` | Allows you to define the index operators for certain index types.

PostgreSQL only. In preview in versions 3.14.0 and later, and in general availability in versions 4.0.0 and later. | +| `where` | **No** | `function` or `object` | Defines a [partial index](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) that only includes rows matching the specified condition. Accepts `raw("SQL expression")` or an object literal like `{ field: value }`.

PostgreSQL, SQLite, SQL Server, and CockroachDB. Requires the `partialIndexes` Preview feature. | The _name_ of the `fields` argument on the `@@index` attribute can be omitted: @@ -2508,9 +2516,15 @@ The `length` and `sort` arguments are added to the relevant field names: #### Signature ```prisma no-lines -@@index(_ fields: FieldReference[], map: String?) +@@index(_ fields: FieldReference[], map: String?, where: raw(String)?) ``` +> **Note**: With the `partialIndexes` Preview feature, the `where` argument is available. Before this Preview feature, the signature was: +> +> ```prisma no-lines +> @@index(_ fields: FieldReference[], map: String?) +> ``` + > **Note**: Until version 3.0.0, the signature was: > > ```prisma no-lines diff --git a/content/200-orm/500-reference/350-database-features.mdx b/content/200-orm/500-reference/350-database-features.mdx index 0e888f4bd0..a9c17fb4e8 100644 --- a/content/200-orm/500-reference/350-database-features.mdx +++ b/content/200-orm/500-reference/350-database-features.mdx @@ -51,7 +51,7 @@ These features are _only_ for relational databases. Supported features for NoSQL | -------------- | :-------------: | :---------------------------------------------------------------------------------------------------------: | :-----------: | :------------: | | `UNIQUE` | ✔️ | [`@unique` and `@@unique`](/orm/prisma-schema/data-model/models#defining-a-unique-field) | ✔️ | ✔️ | | `USING` | PostgreSQL only | [`type`](/orm/prisma-schema/data-model/indexes#configuring-the-access-type-of-indexes-with-type-postgresql) | ✔️ | ✔️ | -| `WHERE` | ✔️ | Not yet | ✔️ | Not yet | +| `WHERE` | ✔️ | [`where`](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) (Preview) | ✔️ | ✔️ | | `(expression)` | ✔️ | Not yet | ✔️ | Not yet | | `INCLUDE` | PostgreSQL and Microsoft SQL Server only | Not yet | ✔️ | Not yet | diff --git a/content/200-orm/500-reference/500-preview-features/050-client-preview-features.mdx b/content/200-orm/500-reference/500-preview-features/050-client-preview-features.mdx index f4f60abfc8..88a8df07b3 100644 --- a/content/200-orm/500-reference/500-preview-features/050-client-preview-features.mdx +++ b/content/200-orm/500-reference/500-preview-features/050-client-preview-features.mdx @@ -22,6 +22,7 @@ The following [Preview](/orm/more/releases#preview) feature flags are available | `strictUndefinedChecks` | [5.20.0](https://github.com/prisma/prisma/releases/tag/5.20.0) | [Submit feedback](https://github.com/prisma/prisma/discussions/25271) | | [`fullTextSearchPostgres`](/orm/prisma-client/queries/full-text-search) | [6.0.0](https://github.com/prisma/prisma/releases/tag/6.0.0) | [Submit feedback](https://github.com/prisma/prisma/issues/25773) | | `shardKeys` | [6.10.0](https://pris.ly/release/6.10.0) | [Submit feedback](https://github.com/prisma/prisma/issues/) | +| [`partialIndexes`](/orm/prisma-schema/data-model/indexes) | [6.17.0](https://pris.ly/release/6.17.0) | [Submit feedback](https://github.com/prisma/prisma/issues/6974) | To enable a Preview feature, [add the feature flag to the `generator` block](#enabling-a-prisma-client-preview-feature) in your `schema.prisma` file. [Share your feedback on all Preview features on GitHub](https://github.com/prisma/prisma/issues/3108). From 03ea14d065ca329f26cdeab85197104924ae7327 Mon Sep 17 00:00:00 2001 From: Jay Lee Date: Wed, 11 Feb 2026 22:45:09 +0900 Subject: [PATCH 2/6] fix(docs): escape camelCase column name in raw() partial index example --- .../100-prisma-schema/20-data-model/30-indexes.mdx | 9 +++++---- 1 file changed, 5 insertions(+), 4 deletions(-) diff --git a/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx b/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx index c735d0d7d6..e1436e4c83 100644 --- a/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx +++ b/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx @@ -545,12 +545,13 @@ You can define a partial index with a raw SQL predicate string using the `raw()` ```prisma file=schema.prisma showLineNumbers model User { - id Int @id - email String - status String + id Int @id + email String + status String + deletedAt DateTime? @@unique([email], where: raw("status = 'active'")) - @@index([email], where: raw("deletedAt IS NULL")) + @@index([email], where: raw("\"deletedAt\" IS NULL")) } ``` From e63e35fcbaf78806031f541fa33101c1ec9a5464 Mon Sep 17 00:00:00 2001 From: Jay Lee Date: Wed, 11 Feb 2026 22:59:10 +0900 Subject: [PATCH 3/6] fix(docs): address review feedback for partial indexes documentation --- .../500-databases/800-sql-server/index.mdx | 2 +- .../300-prisma-migrate/050-getting-started.mdx | 2 +- .../80-unsupported-database-features.mdx | 2 +- .../500-reference/100-prisma-schema-reference.mdx | 12 +++++++++--- 4 files changed, 12 insertions(+), 6 deletions(-) diff --git a/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx b/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx index 61caedd435..f2e0a22f59 100644 --- a/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx +++ b/content/200-orm/050-overview/500-databases/800-sql-server/index.mdx @@ -254,7 +254,7 @@ Microsoft SQL Server [only allows one `NULL` value in a column that has a `UNIQU The standard way to get around this issue is to create a filtered unique index that excludes `NULL` values. This allows you to insert multiple `NULL` values. If you do not create an index in the database, you will get an error if you try to insert more than one `null` value into a column with Prisma Client. -With the [`partialIndexes` Preview feature](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where), you can now define filtered indexes directly in your Prisma schema using the `where` argument on `@@unique` or `@@index`. +With the [`partialIndexes` Preview feature](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where), you can now define filtered indexes directly in your Prisma schema using the `where` argument on `@unique`, `@@unique`, or `@@index`. _However_, creating an index makes it impossible to use `license_number` as a foreign key in the database (or a relation scalar field in corresponding Prisma Schema) diff --git a/content/200-orm/300-prisma-migrate/050-getting-started.mdx b/content/200-orm/300-prisma-migrate/050-getting-started.mdx index 352be989b0..e2098d1edd 100644 --- a/content/200-orm/300-prisma-migrate/050-getting-started.mdx +++ b/content/200-orm/300-prisma-migrate/050-getting-started.mdx @@ -242,7 +242,7 @@ To include [unsupported database features](/orm/prisma-migrate/workflows/unsuppo 1. Open the `migration.sql` file generated in the [Create a baseline migration](#create-a-baseline-migration) section. 1. Modify the generated SQL. For example: - - If the changes are minor, you can append additional custom SQL to the generated migration. The following example creates a stored procedure: + - If the changes are minor, you can append additional custom SQL to the generated migration. The following example creates a trigger function: ```sql /* Generated migration SQL */ diff --git a/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx b/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx index e67864946f..b9102f05d8 100644 --- a/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx +++ b/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx @@ -46,7 +46,7 @@ To customize a migration to include an unsupported feature: npx prisma migrate dev --create-only ``` -1. Open the generated `migration.sql` file and add the unsupported feature - for example, a stored procedure: +1. Open the generated `migration.sql` file and add the unsupported feature - for example, a trigger function: ```sql CREATE OR REPLACE FUNCTION notify_on_insert() diff --git a/content/200-orm/500-reference/100-prisma-schema-reference.mdx b/content/200-orm/500-reference/100-prisma-schema-reference.mdx index ccfa41aa16..5bb09357f9 100644 --- a/content/200-orm/500-reference/100-prisma-schema-reference.mdx +++ b/content/200-orm/500-reference/100-prisma-schema-reference.mdx @@ -2054,9 +2054,11 @@ Defines a unique constraint for this field. #### Signature ```prisma no-lines -@unique(map: String?, length: number?, sort: String?, where: raw(String)?) +@unique(map: String?, length: number?, sort: String?, where: raw(String) | { field: value }?) ``` +> **Note**: The `where` argument accepts either `raw("SQL expression")` for raw SQL predicates or an object literal like `{ field: value }` for type-safe conditions. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. + > **Note**: Before version 4.0.0, or 3.5.0 with the `extendedIndexes` Preview feature enabled, the signature was: > > ```prisma no-lines @@ -2264,9 +2266,11 @@ The `length` and `sort` arguments are added to the relevant field names: #### Signature > ```prisma no-lines -> @@unique(_ fields: FieldReference[], name: String?, map: String?, where: raw(String)?) +> @@unique(_ fields: FieldReference[], name: String?, map: String?, where: raw(String) | { field: value }?) > ``` +> **Note**: The `where` argument accepts either `raw("SQL expression")` for raw SQL predicates or an object literal like `{ field: value }` for type-safe conditions. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. + > **Note**: Before the `partialIndexes` Preview feature, the signature was: > > ```prisma no-lines @@ -2516,9 +2520,11 @@ The `length` and `sort` arguments are added to the relevant field names: #### Signature ```prisma no-lines -@@index(_ fields: FieldReference[], map: String?, where: raw(String)?) +@@index(_ fields: FieldReference[], map: String?, where: raw(String) | { field: value }?) ``` +> **Note**: The `where` argument accepts either `raw("SQL expression")` for raw SQL predicates or an object literal like `{ field: value }` for type-safe conditions. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. + > **Note**: With the `partialIndexes` Preview feature, the `where` argument is available. Before this Preview feature, the signature was: > > ```prisma no-lines From 43d899d87fe9f9c3508f950071b159c906bd4cc6 Mon Sep 17 00:00:00 2001 From: Jay Lee Date: Wed, 11 Feb 2026 23:03:27 +0900 Subject: [PATCH 4/6] fix(docs): use consistent fenced code block for @@unique signature --- .../200-orm/500-reference/100-prisma-schema-reference.mdx | 6 +++--- 1 file changed, 3 insertions(+), 3 deletions(-) diff --git a/content/200-orm/500-reference/100-prisma-schema-reference.mdx b/content/200-orm/500-reference/100-prisma-schema-reference.mdx index 5bb09357f9..a605417232 100644 --- a/content/200-orm/500-reference/100-prisma-schema-reference.mdx +++ b/content/200-orm/500-reference/100-prisma-schema-reference.mdx @@ -2265,9 +2265,9 @@ The `length` and `sort` arguments are added to the relevant field names: #### Signature -> ```prisma no-lines -> @@unique(_ fields: FieldReference[], name: String?, map: String?, where: raw(String) | { field: value }?) -> ``` +```prisma no-lines +@@unique(_ fields: FieldReference[], name: String?, map: String?, where: raw(String) | { field: value }?) +``` > **Note**: The `where` argument accepts either `raw("SQL expression")` for raw SQL predicates or an object literal like `{ field: value }` for type-safe conditions. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. From 9483a817be85a6537b674f49bfda83e1b371f56f Mon Sep 17 00:00:00 2001 From: Jay Lee Date: Wed, 11 Feb 2026 23:09:05 +0900 Subject: [PATCH 5/6] fix(docs): consolidate tips, add @@index SQL output, and clarify introspection notes --- .../100-prisma-schema/20-data-model/30-indexes.mdx | 9 +++++++++ .../300-workflows/80-unsupported-database-features.mdx | 6 +----- .../500-reference/100-prisma-schema-reference.mdx | 8 +------- 3 files changed, 11 insertions(+), 12 deletions(-) diff --git a/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx b/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx index e1436e4c83..c15e39488d 100644 --- a/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx +++ b/content/200-orm/100-prisma-schema/20-data-model/30-indexes.mdx @@ -562,6 +562,7 @@ This generates SQL like: ```sql CREATE UNIQUE INDEX "User_email_key" ON "User" ("email") WHERE (status = 'active'); +CREATE INDEX "User_email_idx" ON "User" ("email") WHERE ("deletedAt" IS NULL); ``` @@ -569,6 +570,7 @@ CREATE UNIQUE INDEX "User_email_key" ON "User" ("email") WHERE (status = 'active ```sql CREATE UNIQUE INDEX "User_email_key" ON "User" ("email") WHERE status = 'active'; +CREATE INDEX "User_email_idx" ON "User" ("email") WHERE "deletedAt" IS NULL; ``` @@ -576,6 +578,7 @@ CREATE UNIQUE INDEX "User_email_key" ON "User" ("email") WHERE status = 'active' ```sql CREATE UNIQUE NONCLUSTERED INDEX [User_email_key] ON [dbo].[User]([email]) WHERE ([status]='active'); +CREATE NONCLUSTERED INDEX [User_email_idx] ON [dbo].[User]([email]) WHERE ([deletedAt] IS NULL); ``` @@ -674,6 +677,12 @@ model User { } ``` +:::note + +The introspected `raw()` string reflects the database's normalized form of the SQL expression, which may differ from what you originally wrote. For example, PostgreSQL adds parentheses and explicit type casts (e.g., `'active'::text`), SQL Server wraps column names in brackets and adds parentheses (e.g., `([status]='active')`), while SQLite generally preserves the original expression as-is. + +::: + ### Upgrading from previous versions :::warning diff --git a/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx b/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx index b9102f05d8..bd9c57d3b2 100644 --- a/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx +++ b/content/200-orm/300-prisma-migrate/300-workflows/80-unsupported-database-features.mdx @@ -19,11 +19,7 @@ To add an unsupported feature to your database, you must [customize a migration] Partial indexes are now supported in Prisma Schema Language via the `where` argument on `@@index`, `@@unique`, and `@unique`. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. You no longer need to customize migrations for partial indexes. -::: - -:::tip - -The Prisma schema is able to represent [unsupported field types](/orm/prisma-schema/data-model/unsupported-database-features#unsupported-field-types) and [native database functions](/orm/prisma-migrate/workflows/native-database-functions). +The Prisma schema is also able to represent [unsupported field types](/orm/prisma-schema/data-model/unsupported-database-features#unsupported-field-types) and [native database functions](/orm/prisma-migrate/workflows/native-database-functions). ::: diff --git a/content/200-orm/500-reference/100-prisma-schema-reference.mdx b/content/200-orm/500-reference/100-prisma-schema-reference.mdx index a605417232..522b5e3d4d 100644 --- a/content/200-orm/500-reference/100-prisma-schema-reference.mdx +++ b/content/200-orm/500-reference/100-prisma-schema-reference.mdx @@ -2271,13 +2271,7 @@ The `length` and `sort` arguments are added to the relevant field names: > **Note**: The `where` argument accepts either `raw("SQL expression")` for raw SQL predicates or an object literal like `{ field: value }` for type-safe conditions. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. -> **Note**: Before the `partialIndexes` Preview feature, the signature was: -> -> ```prisma no-lines -> @@unique(_ fields: FieldReference[], name: String?, map: String?) -> ``` - -> **Note**: Before version 4.0.0, or before version 3.5.0 with the `extendedIndexes` Preview feature enabled, the signature was: +> **Note**: Before the `partialIndexes` Preview feature (and before version 4.0.0 / 3.5.0 with the `extendedIndexes` Preview feature), the signature was: > > ```prisma no-lines > @@unique(_ fields: FieldReference[], name: String?, map: String?) From 9c39a271514c9eb41e3873a5dccde40240b7afdc Mon Sep 17 00:00:00 2001 From: Jay Lee Date: Wed, 11 Feb 2026 23:11:30 +0900 Subject: [PATCH 6/6] fix(docs): add missing clustered arg and historical note to @unique signature --- .../200-orm/500-reference/100-prisma-schema-reference.mdx | 8 +++++++- 1 file changed, 7 insertions(+), 1 deletion(-) diff --git a/content/200-orm/500-reference/100-prisma-schema-reference.mdx b/content/200-orm/500-reference/100-prisma-schema-reference.mdx index 522b5e3d4d..d5b45a73b6 100644 --- a/content/200-orm/500-reference/100-prisma-schema-reference.mdx +++ b/content/200-orm/500-reference/100-prisma-schema-reference.mdx @@ -2054,11 +2054,17 @@ Defines a unique constraint for this field. #### Signature ```prisma no-lines -@unique(map: String?, length: number?, sort: String?, where: raw(String) | { field: value }?) +@unique(map: String?, length: number?, sort: String?, clustered: Boolean?, where: raw(String) | { field: value }?) ``` > **Note**: The `where` argument accepts either `raw("SQL expression")` for raw SQL predicates or an object literal like `{ field: value }` for type-safe conditions. See [Configuring partial indexes](/orm/prisma-schema/data-model/indexes#configuring-partial-indexes-with-where) for details. +> **Note**: Before the `partialIndexes` Preview feature, the signature was: +> +> ```prisma no-lines +> @unique(map: String?, length: number?, sort: String?, clustered: Boolean?) +> ``` + > **Note**: Before version 4.0.0, or 3.5.0 with the `extendedIndexes` Preview feature enabled, the signature was: > > ```prisma no-lines