Skip to content

Add support in migrations for collations in Postgres #662

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 8 commits into from
May 2, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
56 changes: 56 additions & 0 deletions integration_test/myxql/migrations_test.exs
Original file line number Diff line number Diff line change
Expand Up @@ -29,6 +29,41 @@ defmodule Ecto.Integration.MigrationsTest do
end
end

text_variants = ~w/tinytext text mediumtext longtext/a
@text_variants text_variants

collation = "utf8mb4_bin"
@collation collation

defmodule CollateMigration do
use Ecto.Migration

@text_variants text_variants
@collation collation

def change do
create table(:collate_reference) do
add :name, :string, collation: @collation
end

create unique_index(:collate_reference, :name)

create table(:collate) do
add :string, :string, collation: @collation
add :varchar, :varchar, size: 255, collation: @collation
add :name_string, references(:collate_reference, type: :string, column: :name), collation: @collation

for type <- @text_variants do
add type, type, collation: @collation
end
end

alter table(:collate) do
modify :string, :string, collation: "utf8mb4_general_ci"
end
end
end

describe "Migrator" do
@get_lock_command ~s[SELECT GET_LOCK('ecto_Ecto.Integration.PoolRepo', -1)]
@release_lock_command ~s[SELECT RELEASE_LOCK('ecto_Ecto.Integration.PoolRepo')]
Expand Down Expand Up @@ -107,5 +142,26 @@ defmodule Ecto.Integration.MigrationsTest do

assert log =~ "ALTER TABLE `alter_table` ADD `column2` varchar(255) COMMENT 'second column' AFTER `column1`"
end

test "collation can be set on a column" do
num = @base_migration + System.unique_integer([:positive])
assert :ok = Ecto.Migrator.up(PoolRepo, num, CollateMigration, log: false)
query = fn column -> """
SELECT collation_name
FROM information_schema.columns
WHERE table_name = 'collate' AND column_name = '#{column}';
"""
end

assert %{
rows: [["utf8mb4_general_ci"]]
} = Ecto.Adapters.SQL.query!(PoolRepo, query.("string"), [])

for type <- ~w/text name_string/ ++ @text_variants do
assert %{
rows: [[@collation]]
} = Ecto.Adapters.SQL.query!(PoolRepo, query.(type), [])
end
end
end
end
57 changes: 57 additions & 0 deletions integration_test/pg/migrations_test.exs
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,40 @@ defmodule Ecto.Integration.MigrationsTest do
end
end

collation = "POSIX"
@collation collation

text_types = ~w/char varchar text/a
@text_types text_types

defmodule CollateMigration do
use Ecto.Migration

@collation collation
@text_types text_types

def change do
create table(:collate_reference) do
add :name, :string, primary_key: true, collation: @collation
end

create unique_index(:collate_reference, :name)

create table(:collate) do
add :string, :string, collation: @collation
for type <- @text_types do
add type, type, collation: @collation
end

add :name_string, references(:collate_reference, type: :string, column: :name), collation: @collation
end

alter table(:collate) do
modify :string, :string, collation: "C"
end
end
end

test "logs Postgres notice messages" do
log =
capture_log(fn ->
Expand Down Expand Up @@ -145,5 +179,28 @@ defmodule Ecto.Integration.MigrationsTest do
refute down_log =~ @version_delete
refute down_log =~ "commit []"
end

test "collation can be set on a column" do
num = @base_migration + System.unique_integer([:positive])

assert :ok = Ecto.Migrator.up(PoolRepo, num, CollateMigration, log: :info)

query = fn column -> """
SELECT collation_name
FROM information_schema.columns
WHERE table_name = 'collate' AND column_name = '#{column}';
"""
end

assert %{
rows: [["C"]]
} = Ecto.Adapters.SQL.query!(PoolRepo, query.("string"), [])

for type <- @text_types do
assert %{
rows: [[@collation]]
} = Ecto.Adapters.SQL.query!(PoolRepo, query.(type), [])
end
end
end
end
53 changes: 53 additions & 0 deletions integration_test/tds/migrations_test.exs
Original file line number Diff line number Diff line change
Expand Up @@ -15,6 +15,37 @@ defmodule Ecto.Integration.MigrationsTest do
end
end

collation = "Latin1_General_CS_AS"
@collation collation

defmodule CollateMigration do
use Ecto.Migration
@collation collation

def change do
create table(:collate_reference) do
add :name, :string, collation: @collation
end

create unique_index(:collate_reference, :name)

create table(:collate) do
add :string, :string, collation: @collation
add :char, :char, size: 255, collation: @collation
add :nchar, :nchar, size: 255, collation: @collation
add :varchar, :varchar, size: 255, collation: @collation
add :nvarchar, :nvarchar, size: 255, collation: @collation
add :text, :text, collation: @collation
add :ntext, :ntext, collation: @collation
add :name_string, references(:collate_reference, type: :string, column: :name), collation: @collation
end

alter table(:collate) do
modify :string, :string, collation: "Japanese_Bushu_Kakusu_100_CS_AS_KS_WS"
end
end
end

describe "Migrator" do
@get_lock_command ~s(sp_getapplock @Resource = 'ecto_Ecto.Integration.PoolRepo', @LockMode = 'Exclusive', @LockOwner = 'Transaction', @LockTimeout = -1)
@create_table_sql ~s(CREATE TABLE [log_mode_table])
Expand Down Expand Up @@ -77,5 +108,27 @@ defmodule Ecto.Integration.MigrationsTest do
refute down_log =~ @version_delete
refute down_log =~ "commit []"
end

test "collation can be set on a column" do
num = @base_migration + System.unique_integer([:positive])
assert :ok = Ecto.Migrator.up(PoolRepo, num, CollateMigration, log: :info)

query = fn column -> """
SELECT collation_name
FROM information_schema.columns
WHERE table_name = 'collate' AND column_name = '#{column}';
"""
end

assert %{
rows: [["Japanese_Bushu_Kakusu_100_CS_AS_KS_WS"]]
} = Ecto.Adapters.SQL.query!(PoolRepo, query.("string"), [])

for type <- ~w/char varchar nchar nvarchar text ntext/ do
assert %{
rows: [[@collation]]
} = Ecto.Adapters.SQL.query!(PoolRepo, query.(type), [])
end
end
end
end
20 changes: 18 additions & 2 deletions lib/ecto/adapters/myxql/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -1215,7 +1215,13 @@ if Code.ensure_loaded?(MyXQL) do
end

defp column_change(_table, {:add_if_not_exists, name, type, opts}) do
["ADD IF NOT EXISTS ", quote_name(name), ?\s, column_type(type, opts), column_options(opts)]
[
"ADD IF NOT EXISTS ",
quote_name(name),
?\s,
column_type(type, opts),
column_options(opts)
]
end

defp column_change(table, {:modify, name, %Reference{} = ref, opts}) do
Expand Down Expand Up @@ -1264,8 +1270,15 @@ if Code.ensure_loaded?(MyXQL) do
null = Keyword.get(opts, :null)
after_column = Keyword.get(opts, :after)
comment = Keyword.get(opts, :comment)
collation = Keyword.fetch(opts, :collation)

[default_expr(default), null_expr(null), comment_expr(comment), after_expr(after_column)]
[
default_expr(default),
collation_expr(collation),
null_expr(null),
comment_expr(comment),
after_expr(after_column)
]
end

defp comment_expr(comment, create_table? \\ false)
Expand All @@ -1286,6 +1299,9 @@ if Code.ensure_loaded?(MyXQL) do
defp null_expr(true), do: " NULL"
defp null_expr(_), do: []

defp collation_expr({:ok, collation_name}), do: " COLLATE \"#{collation_name}\""
defp collation_expr(_), do: []

defp new_constraint_expr(%Constraint{check: check} = constraint) when is_binary(check) do
[
"CONSTRAINT ",
Expand Down
16 changes: 13 additions & 3 deletions lib/ecto/adapters/postgres/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -1555,6 +1555,8 @@ if Code.ensure_loaded?(Postgrex) do
end

defp column_change(table, {:modify, name, %Reference{} = ref, opts}) do
collation = Keyword.fetch(opts, :collation)

[
drop_reference_expr(opts[:from], table, name),
"ALTER COLUMN ",
Expand All @@ -1564,19 +1566,23 @@ if Code.ensure_loaded?(Postgrex) do
", ADD ",
reference_expr(ref, table, name),
modify_null(name, opts),
modify_default(name, ref.type, opts)
modify_default(name, ref.type, opts),
collation_expr(collation)
]
end

defp column_change(table, {:modify, name, type, opts}) do
collation = Keyword.fetch(opts, :collation)

[
drop_reference_expr(opts[:from], table, name),
"ALTER COLUMN ",
quote_name(name),
" TYPE ",
column_type(type, opts),
modify_null(name, opts),
modify_default(name, type, opts)
modify_default(name, type, opts),
collation_expr(collation)
]
end

Expand Down Expand Up @@ -1624,14 +1630,18 @@ if Code.ensure_loaded?(Postgrex) do
defp column_options(type, opts) do
default = Keyword.fetch(opts, :default)
null = Keyword.get(opts, :null)
collation = Keyword.fetch(opts, :collation)

[default_expr(default, type), null_expr(null)]
[default_expr(default, type), null_expr(null), collation_expr(collation)]
end

defp null_expr(false), do: " NOT NULL"
defp null_expr(true), do: " NULL"
defp null_expr(_), do: []

defp collation_expr({:ok, collation_name}), do: " COLLATE \"#{collation_name}\""
defp collation_expr(_), do: []

defp new_constraint_expr(%Constraint{check: check} = constraint) when is_binary(check) do
[
"CONSTRAINT ",
Expand Down
10 changes: 9 additions & 1 deletion lib/ecto/adapters/tds/connection.ex
Original file line number Diff line number Diff line change
Expand Up @@ -1455,6 +1455,8 @@ if Code.ensure_loaded?(Tds) do
end

defp column_change(statement_prefix, table, {:modify, name, type, opts}) do
collation = Keyword.fetch(opts, :collation)

[
drop_constraint_from_expr(opts[:from], table, name, statement_prefix),
maybe_drop_default_expr(statement_prefix, table, name, opts),
Expand All @@ -1465,6 +1467,7 @@ if Code.ensure_loaded?(Tds) do
" ",
column_type(type, opts),
null_expr(Keyword.get(opts, :null)),
collation_expr(collation),
"; "
],
[column_default_value(statement_prefix, table, name, opts)]
Expand Down Expand Up @@ -1500,7 +1503,9 @@ if Code.ensure_loaded?(Tds) do
defp column_options(table, name, opts) do
default = Keyword.fetch(opts, :default)
null = Keyword.get(opts, :null)
[null_expr(null), default_expr(table, name, default)]
collation = Keyword.fetch(opts, :collation)

[null_expr(null), default_expr(table, name, default), collation_expr(collation)]
end

defp column_default_value(statement_prefix, table, name, opts) do
Expand All @@ -1516,6 +1521,9 @@ if Code.ensure_loaded?(Tds) do
defp null_expr(true), do: [" NULL"]
defp null_expr(_), do: []

defp collation_expr({:ok, collation_name}), do: " COLLATE #{collation_name}"
defp collation_expr(_), do: []

defp default_expr(_table, _name, {:ok, nil}),
do: []

Expand Down
22 changes: 22 additions & 0 deletions lib/ecto/migration.ex
Original file line number Diff line number Diff line change
Expand Up @@ -274,6 +274,26 @@ defmodule Ecto.Migration do

config :app, App.Repo, migration_default_prefix: "my_prefix"

## Collations

Collations can be set on a column with the option `:collation`. This can be
useful when relying on ASCII sorting of characters when using a fractional index
for example. All supported collations and types that support setting a collocation
are not known by `ecto_sql` and specifying an incorrect collation or a collation on
an unsupported type might cause a migration to fail. Be sure to match the collation
on any column that references another column.

def change do
create table(:collate_reference) do
add :name, :string, collation: "POSIX"
end

create table(:collate) do
add :string, :string, collation: "POSIX"
add :name_ref, references(:collate_reference, type: :string, column: :name), collation: "POSIX"
end
end

## Comments

Migrations where you create or alter a table support specifying table
Expand Down Expand Up @@ -1166,6 +1186,7 @@ defmodule Ecto.Migration do
specified.
* `:scale` - the scale of a numeric type. Defaults to `0`.
* `:comment` - adds a comment to the added column.
* `:collation` - the collation of the text type.
* `:after` - positions field after the specified one. Only supported on MySQL,
it is ignored by other databases.
* `:generated` - a string representing the expression for a generated column. See
Expand Down Expand Up @@ -1345,6 +1366,7 @@ defmodule Ecto.Migration do
specified.
* `:scale` - the scale of a numeric type. Defaults to `0`.
* `:comment` - adds a comment to the modified column.
* `:collation` - the collation of the text type.
"""
def modify(column, type, opts \\ []) when is_atom(column) and is_list(opts) do
validate_precision_opts!(opts, column)
Expand Down
Loading