From: Norbert Buchmuller Date: Mon, 8 Oct 2012 17:00:58 +0000 (+0200) Subject: Added support for MySQL prefix indices (also fixes RT#68735) X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=c86d295bab0bd20a2cc2a6e86ee0c639797a88b3;p=dbsrgits%2FSQL-Translator.git Added support for MySQL prefix indices (also fixes RT#68735) --- diff --git a/AUTHORS b/AUTHORS index 8e1cff9..be23aff 100644 --- a/AUTHORS +++ b/AUTHORS @@ -40,6 +40,7 @@ The following people have contributed to the SQLFairy project: - Michal Jurosz - Mikey Melillo - Moritz Onken +- Norbert Buchmuller - Paul Harrington - Peter Rabbitson - Robert Bohne diff --git a/Changes b/Changes index 3a4e1c4..2f808f4 100644 --- a/Changes +++ b/Changes @@ -1,4 +1,10 @@ # ---------------------------------------------------------- +# 0.11017 2012-10-10 +# ---------------------------------------------------------- + +* Added support for MySQL prefix indices (also fixes RT#68735) + +# ---------------------------------------------------------- # 0.11016 2012-10-09 # ---------------------------------------------------------- diff --git a/lib/SQL/Translator.pm b/lib/SQL/Translator.pm index 916f80b..f780550 100644 --- a/lib/SQL/Translator.pm +++ b/lib/SQL/Translator.pm @@ -3,7 +3,7 @@ package SQL::Translator; use Moo; our ( $DEFAULT_SUB, $DEBUG, $ERROR ); -our $VERSION = '0.11016'; +our $VERSION = '0.11017'; $DEBUG = 0 unless defined $DEBUG; $ERROR = ""; diff --git a/lib/SQL/Translator/Parser/MySQL.pm b/lib/SQL/Translator/Parser/MySQL.pm index 40ef243..553f440 100644 --- a/lib/SQL/Translator/Parser/MySQL.pm +++ b/lib/SQL/Translator/Parser/MySQL.pm @@ -735,44 +735,60 @@ foreign_key_def_begin : /constraint/i /foreign key/i WORD primary_key_def : primary_key index_type(?) '(' name_with_opt_paren(s /,/) ')' index_type(?) { + my ($fields, $options) + = SQL::Translator::Parser::MySQL::calculate_fields_and_options( + $item[2][0] || $item[6][0], $item[4] ); + $return = { supertype => 'constraint', type => 'primary_key', - fields => $item[4], - options => $item[2][0] || $item[6][0], + fields => $fields, + options => $options, }; } # In theory, and according to the doc, names should not be allowed here, but # MySQL accept (and ignores) them, so we are not going to be less :) | primary_key index_name_not_using(?) '(' name_with_opt_paren(s /,/) ')' index_type(?) { + my ($fields, $options) + = SQL::Translator::Parser::MySQL::calculate_fields_and_options( + $item[6][0], $item[4] ); + $return = { supertype => 'constraint', type => 'primary_key', - fields => $item[4], - options => $item[6][0], + fields => $fields, + options => $options, }; } unique_key_def : UNIQUE KEY(?) index_name_not_using(?) index_type(?) '(' name_with_opt_paren(s /,/) ')' index_type(?) { + my ($fields, $options) + = SQL::Translator::Parser::MySQL::calculate_fields_and_options( + $item[4][0] || $item[8][0], $item[6] ); + $return = { supertype => 'constraint', name => $item[3][0], type => 'unique', - fields => $item[6], - options => $item[4][0] || $item[8][0], + fields => $fields, + options => $options, } } normal_index : KEY index_name_not_using(?) index_type(?) '(' name_with_opt_paren(s /,/) ')' index_type(?) { + my ($fields, $options) + = SQL::Translator::Parser::MySQL::calculate_fields_and_options( + $item[3][0] || $item[7][0], $item[5] ); + $return = { supertype => 'index', type => 'normal', name => $item[2][0], - fields => $item[5], - options => $item[3][0] || $item[7][0], + fields => $fields, + options => $options, } } @@ -783,26 +799,43 @@ index_type : /using (btree|hash|rtree)/i { $return = uc $1 } fulltext_index : /fulltext/i KEY(?) index_name(?) '(' name_with_opt_paren(s /,/) ')' { + my ($fields, $options) + = SQL::Translator::Parser::MySQL::calculate_fields_and_options( + undef, $item[5] ); + $return = { supertype => 'index', type => 'fulltext', name => $item{'index_name(?)'}[0], - fields => $item[5], + fields => $fields, + # note: according to the MySQL doc, it ignores column index prefixes in + # fulltext index definitions } } spatial_index : /spatial/i KEY(?) index_name(?) '(' name_with_opt_paren(s /,/) ')' { + my ($fields, $options) + = SQL::Translator::Parser::MySQL::calculate_fields_and_options( + undef, $item[5] ); + $return = { supertype => 'index', type => 'spatial', name => $item{'index_name(?)'}[0], - fields => $item[5], + fields => $fields, + # note: according to the MySQL doc, it ignores column index prefixes in + # spatial index definitions } } name_with_opt_paren : NAME parens_value_list(s?) - { $item[2][0] ? "$item[1]($item[2][0][0])" : $item[1] } + { + $return = { + field => $item[1], + prefix_length => $item[2][0] ? $item[2][0][0] : undef, + } + } UNIQUE : /unique/i @@ -965,9 +998,10 @@ sub parse { if ( $fdata->{'has_index'} ) { $table->add_index( - name => '', - type => 'NORMAL', - fields => $fdata->{'name'}, + name => '', + type => 'NORMAL', + fields => $fdata->{'name'}, + options => $fdata->{'options'}, ) or die $table->error; } @@ -989,9 +1023,10 @@ sub parse { for my $idata ( @{ $tdata->{'indices'} || [] } ) { my $index = $table->add_index( - name => $idata->{'name'}, - type => uc $idata->{'type'}, - fields => $idata->{'fields'}, + name => $idata->{'name'}, + type => uc $idata->{'type'}, + fields => $idata->{'fields'}, + options => $idata->{'options'}, ) or die $table->error; } @@ -1159,6 +1194,31 @@ sub normalize_field { } } +# takes the index type and the raw fields item (arrayref of hashrefs as +# returned by name_with_opt_paren()) and returns the arrayref to be passed as +# $index->options and the arrayref to be passed as $index->fields +sub calculate_fields_and_options { + my ($index_type, $field_items) = @_; + + my @fields; + my %prefix_lengths; + foreach my $field_item (@$field_items) { + my $field_name = $field_item->{field}; + + push @fields, $field_name; + + $prefix_lengths{$field_name} = $field_item->{prefix_length} + if defined $field_item->{prefix_length}; + } + + my @options; + push @options, { prefix_length => \%prefix_lengths } + if keys %prefix_lengths; + push @options, $index_type if defined $index_type; + + return (\@fields, \@options); +} + 1; # ------------------------------------------------------------------- diff --git a/lib/SQL/Translator/Producer/MySQL.pm b/lib/SQL/Translator/Producer/MySQL.pm index c0e7637..67cc120 100644 --- a/lib/SQL/Translator/Producer/MySQL.pm +++ b/lib/SQL/Translator/Producer/MySQL.pm @@ -77,6 +77,39 @@ Set the fields charater set and collation order. =back +=head2 Index options + +=over 4 + +=item prefix_length + +This option allows to use a prefix of certain character type (eg. char, +varchar, text) fields in the index. + +The value of this option is a hashref, keys are the field names, values are the +prefix lengths. + +Example: + + $table->add_index( + name => 'idx1', + fields => [ 'id', 'name', 'address' ], + type => 'normal', + options => [ + { + prefix_length => { + name => 10, + address => 20, + } + }, + ], + ); + + # It will generate the following SQL snippet in the table definition: + INDEX `idx1` (`id`, `name`(10), `address`(20)), + +=back + =cut use strict; @@ -91,6 +124,7 @@ $DEBUG = 0 unless defined $DEBUG; my $DEFAULT_MAX_ID_LENGTH = 64; use Data::Dumper; +use List::Util qw(first); use SQL::Translator::Schema::Constants; use SQL::Translator::Utils qw(debug header_comment truncate_id_uniquely parse_mysql_version); @@ -659,6 +693,14 @@ sub create_index my $qf = $options->{quote_field_names} || ''; + my ($prefix_length) = map { ( $_ || {} )->{prefix_length} || {} } + first { ref $_ eq 'HASH' && exists $_->{prefix_length} } + $index->options; + + my @fields = map { + "$qf$_$qf" . (defined $prefix_length->{$_} ? "($prefix_length->{$_})" : "") + } $index->fields; + return join( ' ', map { $_ || () } @@ -669,7 +711,7 @@ sub create_index $options->{max_id_length} || $DEFAULT_MAX_ID_LENGTH ) . $qf : '', - '(' . $qf . join( "$qf, $qf", $index->fields ) . $qf . ')' + '(' . join(", ", @fields) . ')' ); } diff --git a/t/02mysql-parser.t b/t/02mysql-parser.t index dbcde4e..9d1cf1d 100644 --- a/t/02mysql-parser.t +++ b/t/02mysql-parser.t @@ -12,7 +12,7 @@ use Test::SQL::Translator qw(maybe_plan); use FindBin qw/$Bin/; BEGIN { - maybe_plan(346, "SQL::Translator::Parser::MySQL"); + maybe_plan(347, "SQL::Translator::Parser::MySQL"); SQL::Translator::Parser::MySQL->import('parse'); } @@ -233,7 +233,9 @@ BEGIN { my $i3 = shift @indices; is( $i3->name, 'name_idx', 'Name is "name_idx"' ); is( $i3->type, NORMAL, 'Normal index' ); - is( join(',', $i3->fields ), 'name(10)', 'Index is on field "name(10)"' ); + is( join(',', $i3->fields ), 'name', 'Index is on field "name"' ); + is_deeply( [ $i3->options ], [ { prefix_length => { name => 10 } } ], + 'Index is on the first 10 chars' ); my @constraints = $table->get_constraints; is( scalar @constraints, 2, 'Right number of constraints (2)' ); diff --git a/t/38-mysql-producer.t b/t/38-mysql-producer.t index 57b04d1..8223b28 100644 --- a/t/38-mysql-producer.t +++ b/t/38-mysql-producer.t @@ -67,6 +67,24 @@ schema: mysql_charset: utf8 mysql_collate: utf8_general_ci order: 4 + indices: + - type: NORMAL + fields: + - name + name: index_on_prefix_1 + options: + prefix_length: + name: 10 + - type: NORMAL + fields: + - id + - name + - swedish_name + name: index_on_prefix_2 + options: + prefix_length: + name: 10 + swedish_name: 20 constraints: - type: UNIQUE fields: @@ -191,6 +209,8 @@ my @stmts = ( `name` varchar(32) NULL, `swedish_name` varchar(32) character set swe7 NULL, `description` text character set utf8 collate utf8_general_ci NULL, + INDEX `index_on_prefix_1` (`name`(10)), + INDEX `index_on_prefix_2` (`id`, `name`(10), `swedish_name`(20)), PRIMARY KEY (`id`), UNIQUE `idx_unique_name` (`name`) ) ENGINE=InnoDB DEFAULT CHARACTER SET latin1 COLLATE latin1_danish_ci",