From 22405c14bc7cc98eeed89a4a1bfd1cd222581628 Mon Sep 17 00:00:00 2001 From: Jon Harrell <4829245+jharrell@users.noreply.github.com> Date: Wed, 3 Jul 2024 14:17:44 -0500 Subject: [PATCH 1/2] better docs for case-insensitive filtering with SQLite. Resolves DA-460. Resolves #1858. --- .../100-queries/070-case-sensitivity.mdx | 30 ++++++++++++++++--- 1 file changed, 26 insertions(+), 4 deletions(-) diff --git a/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx b/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx index a263861e5c..28caa6ea8e 100644 --- a/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx +++ b/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx @@ -170,13 +170,35 @@ The MongoDB uses a RegEx rule for case-insensitive filtering. ### SQLite provider -By default, SQLite itself only [supports case-insensitive comparisons of ASCII characters](https://www.sqlite.org/faq.html#q18). Therefore, Prisma Client does not offer support for case-insensitive filtering with SQLite. +By default, text fields created by Prisma Client in SQLite databases do not support case-insensitive filtering. In SQLite, only [case-insensitive comparisons of ASCII characters](https://www.sqlite.org/faq.html#q18) are possible. -To enable limited support (ASCII only) for case-insensitive filtering on a per-column basis, use `COLLATE NOCASE` when you define table columns: +To enable limited support (ASCII only) for case-insensitive filtering on a per-column basis, you will need to add `COLLATE NOCASE` when you define a text column. For example, if you had the following Prisma Schema model: + +```prisma +model User { + id Int @id + email String +} +``` + +and used `prisma migrate dev --create-only` to create the following migration file: + +```sql +-- CreateTable +CREATE TABLE "TestUser" ( + "id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + "email" TEXT NOT NULL +); +``` + +You would need to add `COLLATE NOCASE` to the `email` column in order to make case-insensitive filtering possible: ```sql -CREATE TABLE mytable ( - sample TEXT COLLATE NOCASE /* collating sequence NOCASE */ +-- CreateTable +CREATE TABLE "TestUser" ( + "id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + //highlight-next-line + "email" TEXT NOT NULL COLLATE NOCASE ); ``` From 0f2c7fb467f325db940ab272673a1074d7b08f1b Mon Sep 17 00:00:00 2001 From: Jon Harrell <4829245+jharrell@users.noreply.github.com> Date: Tue, 9 Jul 2024 12:44:10 -0500 Subject: [PATCH 2/2] split recommendations into adding or editing a column --- .../100-queries/070-case-sensitivity.mdx | 44 +++++++++++++++++-- 1 file changed, 40 insertions(+), 4 deletions(-) diff --git a/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx b/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx index 28caa6ea8e..c545b42052 100644 --- a/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx +++ b/content/200-orm/200-prisma-client/100-queries/070-case-sensitivity.mdx @@ -172,7 +172,13 @@ The MongoDB uses a RegEx rule for case-insensitive filtering. By default, text fields created by Prisma Client in SQLite databases do not support case-insensitive filtering. In SQLite, only [case-insensitive comparisons of ASCII characters](https://www.sqlite.org/faq.html#q18) are possible. -To enable limited support (ASCII only) for case-insensitive filtering on a per-column basis, you will need to add `COLLATE NOCASE` when you define a text column. For example, if you had the following Prisma Schema model: +To enable limited support (ASCII only) for case-insensitive filtering on a per-column basis, you will need to add `COLLATE NOCASE` when you define a text column. + +#### Adding case-insensitive filtering to a new column. + +To add case-insensitive filtering to a new column, you will need to modify the migration file that is created by Prisma Client. + +Taking the following Prisma Schema model: ```prisma model User { @@ -181,11 +187,11 @@ model User { } ``` -and used `prisma migrate dev --create-only` to create the following migration file: +and using `prisma migrate dev --create-only` to create the following migration file: ```sql -- CreateTable -CREATE TABLE "TestUser" ( +CREATE TABLE "User" ( "id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, "email" TEXT NOT NULL ); @@ -195,13 +201,43 @@ You would need to add `COLLATE NOCASE` to the `email` column in order to make ca ```sql -- CreateTable -CREATE TABLE "TestUser" ( +CREATE TABLE "User" ( "id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, //highlight-next-line "email" TEXT NOT NULL COLLATE NOCASE ); ``` +#### Adding case-insensitive filtering to an existing column. + +Since columns cannot be updated in SQLite, `COLLATE NOCASE` can only be added to an existing column by creating a blank migration file and migrating data to a new table. + +Taking the following Prisma Schema model: + +```prisma +model User { + id Int @id + email String +} +``` + +and using `prisma migrate dev --create-only` to create an empty migration file, you will need to rename the current `User` table and create a new `User` table with `COLLATE NOCASE`. + +```sql +-- UpdateTable +ALTER TABLE "User" RENAME TO "User_old"; + +CREATE TABLE "User" ( + "id" INTEGER NOT NULL PRIMARY KEY AUTOINCREMENT, + "email" TEXT NOT NULL COLLATE NOCASE +); + +INSERT INTO "User" (id, email) +SELECT id, email FROM "User_old"; + +DROP TABLE "User_old"; +``` + ### Microsoft SQL Server provider Microsoft SQL Server uses **case-insensitive collation** by default. Therefore, filtering with Prisma Client and Microsoft SQL Server is case-insensitive by default.