[Rt-commit] r14663 - in rtfm/trunk: . etc/upgrade

falcone at bestpractical.com falcone at bestpractical.com
Wed Jul 30 16:06:06 EDT 2008


Author: falcone
Date: Wed Jul 30 16:06:01 2008
New Revision: 14663

Added:
   rtfm/trunk/etc/schema.mysql-4.1
   rtfm/trunk/etc/upgrade/schema.mysql-4.0-4.1.pl   (contents, props changed)
Modified:
   rtfm/trunk/   (props changed)

Log:
 r36395 at ketch:  falcone | 2008-07-30 11:53:55 -0400
 * scrips for upgrading from mysql 4.0 to later databases
 * schema for mysql 4.1 so that table types mesh with rt-3.8


Added: rtfm/trunk/etc/schema.mysql-4.1
==============================================================================
--- (empty file)
+++ rtfm/trunk/etc/schema.mysql-4.1	Wed Jul 30 16:06:01 2008
@@ -0,0 +1,46 @@
+CREATE TABLE FM_Classes (
+  id int(11) NOT NULL auto_increment,
+  Name varchar(255) NOT NULL default '',
+  Description varchar(255) NOT NULL default '',
+  SortOrder int(11) NOT NULL default '0',
+  Disabled int(2) NOT NULL default '0',
+  Creator int(11) NOT NULL default '0',
+  Created datetime default NULL,
+  LastUpdatedBy int(11) NOT NULL default '0',
+  LastUpdated datetime default NULL,
+  HotList int(2) NOT NULL default '0',
+  PRIMARY KEY  (id)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE TABLE FM_Articles (
+  id int(11) NOT NULL auto_increment,
+  Name varchar(255) NOT NULL default '',
+  Summary varchar(255) NOT NULL default '',
+  SortOrder int(11) NOT NULL default '0',
+  Class int(11) NOT NULL default '0',
+  Parent int(11) NOT NULL default '0',
+  URI varchar(255) character set ascii default NULL,
+  Creator int(11) NOT NULL default '0',
+  Created datetime default NULL,
+  LastUpdatedBy int(11) NOT NULL default '0',
+  LastUpdated datetime default NULL,
+  PRIMARY KEY  (id)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE TABLE FM_Topics (
+  id int(11) NOT NULL auto_increment,
+  Parent int(11) NOT NULL default '0',
+  Name varchar(255) NOT NULL default '',
+  Description varchar(255) NOT NULL default '',
+  ObjectType varchar(64) character set ascii NOT NULL default '',
+  ObjectId int(11) NOT NULL default '0',
+  PRIMARY KEY  (id)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;
+
+CREATE TABLE FM_ObjectTopics (
+  id int(11) NOT NULL auto_increment,
+  Topic int(11) NOT NULL default '0',
+  ObjectType varchar(64) character set ascii NOT NULL default '',
+  ObjectId int(11) NOT NULL default '0',
+  PRIMARY KEY  (id)
+) ENGINE=InnoDB DEFAULT CHARSET=utf8;

Added: rtfm/trunk/etc/upgrade/schema.mysql-4.0-4.1.pl
==============================================================================
--- (empty file)
+++ rtfm/trunk/etc/upgrade/schema.mysql-4.0-4.1.pl	Wed Jul 30 16:06:01 2008
@@ -0,0 +1,227 @@
+#!/usr/bin/perl
+
+use strict;
+use warnings;
+
+use DBI;
+use DBD::mysql 4.002;
+
+unless (@ARGV) {
+    print STDERR "usage: $0 db_name db_user db_password\n";
+    exit 1;
+}
+
+# pretty correct support of charsets has been introduced in mysql 4.1
+# as RT doesn't use it may result in issues:
+# 1) data corruptions when default charset of mysql server has data restrictions like utf8
+# 2) wrong ordering (collations)
+
+# we have to define correct types for all columns. RT uses UTF-8, ascii and binary.
+# * ascii is subset of many mysql's charsets except may be one or two rare where some ascii
+#   characters replaced with local
+# * for many charsets mysql allows us to store any octets sequences even when those are
+#   invalid for this particula set, for example we can store UTF-8 data in latin1
+#   column and fetch it as UTF-8, however sorting will be wrong
+
+# here is tricky algorithm to change column to desired charset:
+# * text to binary convertion is pretty straight forward except that text types
+#   have length definitions in terms of characters and in some cases we must
+#   use longer binary types to satisfy space requirements
+# * binary to text is much easier as we know that there is ascii or UTF-8 then
+#   we just make convertion, also 32 chars are long enough to store 32 bytes, so
+#   length changes is not required
+# * text to text convertion is trickier. no matter what is the current character set
+#   of the column we know that there is either ascii or UTF-8, so we can not use
+#   direct convertion, instead we do text to binary plus binary to text convertion
+#   instead
+# * as well we add charset definition for all tables and for the DB as well,
+#   so all new columns by default will be in UTF-8 charset
+
+my @tables = qw(
+    FM_Articles
+    FM_Classes
+    FM_ObjectTopics
+    FM_Topics
+);
+
+my %charset = (
+    FM_Articles => {
+        Name => 'utf8',
+        Summary => 'utf8',
+        URI => 'ascii',
+    },
+    FM_Classes => {
+        Name => 'utf8',
+        Description => 'utf8',
+    },
+    FM_ObjectTopics => {
+        ObjectType => 'ascii',
+    },
+    FM_Topics => {
+        Name => 'utf8',
+        Description => 'utf8',
+        ObjectType => 'ascii',
+    },
+);
+
+my %max_type_length = (
+    char       => int 1<<8,
+    varchar    => int 1<<8,
+    tinytext   => int 1<<8,
+    mediumtext => int 1<<16,
+    text       => int 1<<24,
+    longtext   => int 1<<32,
+);
+
+my @sql_commands;
+
+my ($db_name, $db_user, $db_pass) = (shift, shift, shift);
+my $dbh = DBI->connect("dbi:mysql:$db_name", $db_user, $db_pass, { RaiseError => 1 });
+
+
+# do this from the RT level
+#push @sql_commands, qq{ALTER DATABASE $db_name DEFAULT CHARACTER SET utf8};
+convert_table($_) foreach @tables;
+
+print join "\n", map(/;$/? $_ : "$_;", @sql_commands), "";
+exit 0;
+
+sub convert_table {
+    my $table = shift;
+    push @sql_commands, qq{ALTER TABLE $table DEFAULT CHARACTER SET utf8};
+
+    my $sth = $dbh->column_info( undef, $db_name, $table, undef );
+    $sth->execute;
+    while ( my $info = $sth->fetchrow_hashref ) {
+        convert_column(%$info);
+    }
+}
+
+sub convert_column {
+    my %info = @_;
+    my $table = $info{'TABLE_NAME'};
+    my $column = $info{'COLUMN_NAME'};
+    my $type = $info{'TYPE_NAME'};
+    return unless $type =~ /(CHAR|TEXT|BLOB|BINARY)$/i;
+
+    my $required_charset = $charset{$table}{$column};
+    unless ( $required_charset ) {
+        print STDERR join(".", @info{'TABLE_SCHEM', 'TABLE_NAME', 'COLUMN_NAME'})
+            ." has type $type however mapping is missing.\n";
+        return;
+    }
+
+    my $collation = column_info($table, $column)->{'collation'};
+    my $current_charset = $collation? (split /_/, $collation)[0]: 'binary';
+    return if $required_charset eq $current_charset;
+
+    if ( $required_charset eq 'binary' ) {
+        push @sql_commands, char_to_binary(%info);
+    }
+    elsif ( $current_charset eq 'binary' ) {
+        push @sql_commands, binary_to_char( $required_charset, %info);
+    } else {
+        push @sql_commands, char_to_char( $required_charset, %info);
+    }
+}
+
+sub char_to_binary {
+    my %info = @_;
+
+    my $table = $info{'TABLE_NAME'};
+    my $column = $info{'COLUMN_NAME'};
+    my $new_type = calc_suitable_binary_type(%info);
+
+    return "ALTER TABLE $table MODIFY $column ". $new_type ." ". build_column_definition(%info);
+}
+
+sub binary_to_char {
+    my ($charset, %info) = @_;
+
+    my $table = $info{'TABLE_NAME'};
+    my $column = $info{'COLUMN_NAME'};
+    my $new_type = lc $info{'TYPE_NAME'};
+    if ( $new_type =~ /binary/ ) {
+        $new_type =~ s/binary/char/;
+        $new_type .= '('. $info{'COLUMN_SIZE'} .')';
+    } else {
+        $new_type =~ s/blob/text/;
+    }
+
+    return "ALTER TABLE $table MODIFY $column ". uc($new_type)
+        ." CHARACTER SET ". $charset
+        ." ". build_column_definition(%info);
+}
+
+sub char_to_char {
+    my ($charset, %info) = @_;
+
+    my $table = $info{'TABLE_NAME'};
+    my $column = $info{'COLUMN_NAME'};
+    my $new_type = $info{'mysql_type_name'};
+
+    return char_to_binary(%info),
+        "ALTER TABLE $table MODIFY $column ". uc($new_type)
+            ." CHARACTER SET ". $charset
+            ." ". build_column_definition(%info);
+}
+
+sub calc_suitable_binary_type {
+    my %info = @_;
+    my $type = lc $info{'TYPE_NAME'};
+    return 'LONGBLOB' if $type eq 'longtext';
+
+    my $current_max_byte_length = column_byte_length(@info{qw(TABLE_NAME COLUMN_NAME)}) || 0;
+    if ( $max_type_length{ $type } > $current_max_byte_length ) {
+        if ( $type eq 'varchar' || $type eq 'char' ) {
+            my $new_type = $type;
+            $new_type =~ s/char/binary/;
+            $new_type .= $info{'COLUMN_SIZE'} >= $current_max_byte_length
+                ? '('. $info{'COLUMN_SIZE'} .')'
+                : '('. $current_max_byte_length .')';
+            return uc $new_type;
+        } else {
+            my $new_type = $type;
+            $new_type =~ s/text/blob/;
+            return uc $new_type;
+        }
+    } else {
+        my $new_type;
+        foreach ( sort { $max_type_length{$a} <=> $max_type_length{$b} } keys %max_type_length ) {
+            next if $max_type_length{ $_ } <= $current_max_byte_length;
+            
+            $new_type = $_; last;
+        }
+        $new_type =~ s/text/blob/;
+        return uc $new_type;
+    }
+}
+
+sub build_column_definition {
+    my %info = @_;
+
+    my $res = '';
+    $res .= 'NOT ' unless $info{'NULLABLE'};
+    $res .= 'NULL';
+    my $default = column_info(@info{qw(TABLE_NAME COLUMN_NAME)})->{default};
+    if ( defined $default ) {
+        $res .= ' DEFAULT '. $dbh->quote($default);
+    } elsif ( $info{'NULLABLE'} ) {
+        $res .= ' DEFAULT NULL';
+    }
+    $res .= ' AUTO_INCREMENT' if $info{'mysql_is_auto_increment'};
+    return $res;
+}
+
+sub column_byte_length {
+    my ($table, $column) = @_;
+    return $dbh->selectrow_arrayref("SELECT MAX(LENGTH(". $dbh->quote($column) .")) FROM $table")->[0];
+}
+
+sub column_info {
+    my ($table, $column) = @_;
+    # XXX: DBD::mysql doesn't provide this info, may be will do in 4.0007 if I'll write a patch
+    local $dbh->{FetchHashKeyName} = 'NAME_lc';
+    return $dbh->selectrow_hashref("SHOW FULL COLUMNS FROM $table LIKE " . $dbh->quote($column));
+}
+


More information about the Rt-commit mailing list