Skip to content

Commit

Permalink
Add Expression Indexes and Operator Classes support for PostgreSQL
Browse files Browse the repository at this point in the history
Example:

    create_table :users do |t|
      t.string :name
      t.index 'lower(name) varchar_pattern_ops'
    end

Fixes #19090.
Fixes #21765.
Fixes #21819.
Fixes #24359.

Signed-off-by: Jeremy Daer <jeremydaer@gmail.com>
  • Loading branch information
kamipo authored and jeremy committed Apr 24, 2016
1 parent c41ef01 commit edc2b77
Show file tree
Hide file tree
Showing 10 changed files with 112 additions and 38 deletions.
13 changes: 13 additions & 0 deletions activerecord/CHANGELOG.md
Original file line number Diff line number Diff line change
@@ -1,3 +1,16 @@
* PostgreSQL: Support Expression Indexes and Operator Classes.

Example:

create_table :users do |t|
t.string :name
t.index 'lower(name) varchar_pattern_ops'
end

Fixes #19090, #21765, #21819, #24359.

*Ryuta Kamizono*

* MySQL: Prepared statements support.

To enable, set `prepared_statements: true` in config/database.yml.
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -1110,15 +1110,19 @@ def update_table_definition(table_name, base) #:nodoc:
Table.new(table_name, base)
end

def add_index_options(table_name, column_name, comment: nil, **options) #:nodoc:
column_names = Array(column_name)
def add_index_options(table_name, column_name, comment: nil, **options) # :nodoc:
if column_name.is_a?(String) && /\W/ === column_name
column_names = column_name
else
column_names = Array(column_name)
end

options.assert_valid_keys(:unique, :order, :name, :where, :length, :internal, :using, :algorithm, :type)

index_type = options[:type].to_s if options.key?(:type)
index_type ||= options[:unique] ? "UNIQUE" : ""
index_name = options[:name].to_s if options.key?(:name)
index_name ||= index_name(table_name, column: column_names)
index_name ||= index_name(table_name, index_name_options(column_names))
max_index_length = options.fetch(:internal, false) ? index_name_length : allowed_index_name_length

if options.key?(:algorithm)
Expand Down Expand Up @@ -1174,6 +1178,8 @@ def add_index_sort_order(option_strings, column_names, options = {})

# Overridden by the MySQL adapter for supporting index lengths
def quoted_columns_for_index(column_names, options = {})
return [column_names] if column_names.is_a?(String)

option_strings = Hash[column_names.map {|name| [name, '']}]

# add index sort order if supported
Expand Down Expand Up @@ -1249,6 +1255,14 @@ def create_alter_table(name)
AlterTable.new create_table_definition(name)
end

def index_name_options(column_names) # :nodoc:
if column_names.is_a?(String)
column_names = column_names.scan(/\w+/).join('_')
end

{ column: column_names }
end

def foreign_key_name(table_name, options) # :nodoc:
identifier = "#{table_name}_#{options.fetch(:column)}_fk"
hashed_identifier = Digest::SHA256.hexdigest(identifier).first(10)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -248,6 +248,11 @@ def supports_partial_index?
false
end

# Does this adapter support expression indices?
def supports_expression_index?
false
end

# Does this adapter support explain?
def supports_explain?
false
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -175,7 +175,10 @@ def indexes(table_name, name = nil)

result = query(<<-SQL, 'SCHEMA')
SELECT distinct i.relname, d.indisunique, d.indkey, pg_get_indexdef(d.indexrelid), t.oid,
pg_catalog.obj_description(i.oid, 'pg_class') AS comment
pg_catalog.obj_description(i.oid, 'pg_class') AS comment,
(SELECT COUNT(*) FROM pg_opclass o
JOIN (SELECT unnest(string_to_array(d.indclass::text, ' '))::int oid) c
ON o.oid = c.oid WHERE o.opcdefault = 'f')
FROM pg_class t
INNER JOIN pg_index d ON t.oid = d.indrelid
INNER JOIN pg_class i ON d.indexrelid = i.oid
Expand All @@ -194,25 +197,27 @@ def indexes(table_name, name = nil)
inddef = row[3]
oid = row[4]
comment = row[5]
opclass = row[6]

columns = Hash[query(<<-SQL, "SCHEMA")]
SELECT a.attnum, a.attname
FROM pg_attribute a
WHERE a.attrelid = #{oid}
AND a.attnum IN (#{indkey.join(",")})
SQL
using, expressions, where = inddef.scan(/ USING (\w+?) \((.+?)\)(?: WHERE (.+))?\z/).flatten

column_names = columns.values_at(*indkey).compact
if indkey.include?(0) || opclass > 0
columns = expressions
else
columns = Hash[query(<<-SQL.strip_heredoc, "SCHEMA")].values_at(*indkey).compact
SELECT a.attnum, a.attname
FROM pg_attribute a
WHERE a.attrelid = #{oid}
AND a.attnum IN (#{indkey.join(",")})
SQL

unless column_names.empty?
# add info on sort order for columns (only desc order is explicitly specified, asc is the default)
desc_order_columns = inddef.scan(/(\w+) DESC/).flatten
orders = desc_order_columns.any? ? Hash[desc_order_columns.map {|order_column| [order_column, :desc]}] : {}
where = inddef.scan(/WHERE (.+)$/).flatten[0]
using = inddef.scan(/USING (.+?) /).flatten[0].to_sym

IndexDefinition.new(table_name, index_name, unique, column_names, [], orders, where, nil, using, comment)
orders = Hash[
expressions.scan(/(\w+) DESC/).flatten.map { |order_column| [order_column, :desc] }
]
end

IndexDefinition.new(table_name, index_name, unique, columns, [], orders, where, nil, using.to_sym, comment)
end.compact
end

Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -140,6 +140,10 @@ def supports_partial_index?
true
end

def supports_expression_index?
true
end

def supports_transaction_isolation?
true
end
Expand Down
19 changes: 13 additions & 6 deletions activerecord/test/cases/adapters/postgresql/active_schema_test.rb
Original file line number Diff line number Diff line change
Expand Up @@ -28,7 +28,13 @@ def test_add_index
ActiveRecord::ConnectionAdapters::PostgreSQLAdapter.send(:define_method, :index_name_exists?) { |*| false }

expected = %(CREATE UNIQUE INDEX "index_people_on_last_name" ON "people" ("last_name") WHERE state = 'active')
assert_equal expected, add_index(:people, :last_name, :unique => true, :where => "state = 'active'")
assert_equal expected, add_index(:people, :last_name, unique: true, where: "state = 'active'")

expected = %(CREATE UNIQUE INDEX "index_people_on_lower_last_name" ON "people" (lower(last_name)))
assert_equal expected, add_index(:people, 'lower(last_name)', unique: true)

expected = %(CREATE UNIQUE INDEX "index_people_on_last_name_varchar_pattern_ops" ON "people" (last_name varchar_pattern_ops))
assert_equal expected, add_index(:people, 'last_name varchar_pattern_ops', unique: true)

expected = %(CREATE INDEX CONCURRENTLY "index_people_on_last_name" ON "people" ("last_name"))
assert_equal expected, add_index(:people, :last_name, algorithm: :concurrently)
Expand All @@ -39,16 +45,17 @@ def test_add_index

expected = %(CREATE INDEX CONCURRENTLY "index_people_on_last_name" ON "people" USING #{type} ("last_name"))
assert_equal expected, add_index(:people, :last_name, using: type, algorithm: :concurrently)

expected = %(CREATE UNIQUE INDEX "index_people_on_last_name" ON "people" USING #{type} ("last_name") WHERE state = 'active')
assert_equal expected, add_index(:people, :last_name, using: type, unique: true, where: "state = 'active'")

expected = %(CREATE UNIQUE INDEX "index_people_on_lower_last_name" ON "people" USING #{type} (lower(last_name)))
assert_equal expected, add_index(:people, 'lower(last_name)', using: type, unique: true)
end

assert_raise ArgumentError do
add_index(:people, :last_name, algorithm: :copy)
end
expected = %(CREATE UNIQUE INDEX "index_people_on_last_name" ON "people" USING gist ("last_name"))
assert_equal expected, add_index(:people, :last_name, :unique => true, :using => :gist)

expected = %(CREATE UNIQUE INDEX "index_people_on_last_name" ON "people" USING gist ("last_name") WHERE state = 'active')
assert_equal expected, add_index(:people, :last_name, :unique => true, :where => "state = 'active'", :using => :gist)

ActiveRecord::ConnectionAdapters::PostgreSQLAdapter.send :remove_method, :index_name_exists?
end
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -259,6 +259,22 @@ def test_partial_index
end
end

def test_expression_index
with_example_table do
@connection.add_index 'ex', 'mod(id, 10), abs(number)', name: 'expression'
index = @connection.indexes('ex').find { |idx| idx.name == 'expression' }
assert_equal 'mod(id, 10), abs(number)', index.columns
end
end

def test_index_with_opclass
with_example_table do
@connection.add_index 'ex', 'data varchar_pattern_ops', name: 'with_opclass'
index = @connection.indexes('ex').find { |idx| idx.name == 'with_opclass' }
assert_equal 'data varchar_pattern_ops', index.columns
end
end

def test_columns_for_distinct_zero_orders
assert_equal "posts.id",
@connection.columns_for_distinct("posts.id", [])
Expand Down
30 changes: 17 additions & 13 deletions activerecord/test/cases/adapters/postgresql/schema_test.rb
Original file line number Diff line number Diff line change
Expand Up @@ -325,7 +325,7 @@ def test_dump_indexes_for_schema_multiple_schemas_in_search_path

def test_dump_indexes_for_table_with_scheme_specified_in_name
indexes = @connection.indexes("#{SCHEMA_NAME}.#{TABLE_NAME}")
assert_equal 4, indexes.size
assert_equal 5, indexes.size
end

def test_with_uppercase_index_name
Expand Down Expand Up @@ -449,18 +449,22 @@ def columns(table_name)
def do_dump_index_tests_for_schema(this_schema_name, first_index_column_name, second_index_column_name, third_index_column_name, fourth_index_column_name)
with_schema_search_path(this_schema_name) do
indexes = @connection.indexes(TABLE_NAME).sort_by(&:name)
assert_equal 4,indexes.size

do_dump_index_assertions_for_one_index(indexes[0], INDEX_A_NAME, first_index_column_name)
do_dump_index_assertions_for_one_index(indexes[1], INDEX_B_NAME, second_index_column_name)
do_dump_index_assertions_for_one_index(indexes[2], INDEX_D_NAME, third_index_column_name)
do_dump_index_assertions_for_one_index(indexes[3], INDEX_E_NAME, fourth_index_column_name)

indexes.select{|i| i.name != INDEX_E_NAME}.each do |index|
assert_equal :btree, index.using
end
assert_equal :gin, indexes.select{|i| i.name == INDEX_E_NAME}[0].using
assert_equal :desc, indexes.select{|i| i.name == INDEX_D_NAME}[0].orders[INDEX_D_COLUMN]
assert_equal 5, indexes.size

index_a, index_b, index_c, index_d, index_e = indexes

do_dump_index_assertions_for_one_index(index_a, INDEX_A_NAME, first_index_column_name)
do_dump_index_assertions_for_one_index(index_b, INDEX_B_NAME, second_index_column_name)
do_dump_index_assertions_for_one_index(index_d, INDEX_D_NAME, third_index_column_name)
do_dump_index_assertions_for_one_index(index_e, INDEX_E_NAME, fourth_index_column_name)

assert_equal :btree, index_a.using
assert_equal :btree, index_b.using
assert_equal :gin, index_c.using
assert_equal :btree, index_d.using
assert_equal :gin, index_e.using

assert_equal :desc, index_d.orders[INDEX_D_COLUMN]
end
end

Expand Down
7 changes: 6 additions & 1 deletion activerecord/test/cases/schema_dumper_test.rb
Original file line number Diff line number Diff line change
Expand Up @@ -92,7 +92,7 @@ def test_types_line_up
next if column_set.empty?

lengths = column_set.map do |column|
if match = column.match(/\bt\.\w+\s+"/)
if match = column.match(/\bt\.\w+\s+(?="\w+?")/)
match[0].length
end
end.compact
Expand Down Expand Up @@ -279,6 +279,11 @@ def test_schema_dump_allows_array_of_decimal_defaults
assert_match %r{t\.decimal\s+"decimal_array_default",\s+default: \["1.23", "3.45"\],\s+array: true}, output
end

def test_schema_dump_expression_indices
index_definition = standard_dump.split(/\n/).grep(/t\.index.*company_expression_index/).first.strip
assert_equal 't.index "lower((name)::text)", name: "company_expression_index", using: :btree', index_definition
end

if ActiveRecord::Base.connection.supports_extensions?
def test_schema_dump_includes_extensions
connection = ActiveRecord::Base.connection
Expand Down
1 change: 1 addition & 0 deletions activerecord/test/schema/schema.rb
Original file line number Diff line number Diff line change
Expand Up @@ -199,6 +199,7 @@
t.index [:firm_id, :type, :rating], name: "company_index"
t.index [:firm_id, :type], name: "company_partial_index", where: "rating > 10"
t.index :name, name: 'company_name_index', using: :btree
t.index 'lower(name)', name: "company_expression_index" if supports_expression_index?
end

create_table :content, force: true do |t|
Expand Down

0 comments on commit edc2b77

Please sign in to comment.