1 package SQL::Translator::Producer::MySQL;
3 # -------------------------------------------------------------------
4 # $Id: MySQL.pm,v 1.26 2003-08-18 15:43:14 kycl4rk Exp $
5 # -------------------------------------------------------------------
6 # Copyright (C) 2003 Ken Y. Clark <kclark@cpan.org>,
7 # darren chamberlain <darren@cpan.org>,
8 # Chris Mungall <cjm@fruitfly.org>
10 # This program is free software; you can redistribute it and/or
11 # modify it under the terms of the GNU General Public License as
12 # published by the Free Software Foundation; version 2.
14 # This program is distributed in the hope that it will be useful, but
15 # WITHOUT ANY WARRANTY; without even the implied warranty of
16 # MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
17 # General Public License for more details.
19 # You should have received a copy of the GNU General Public License
20 # along with this program; if not, write to the Free Software
21 # Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
23 # -------------------------------------------------------------------
26 use vars qw[ $VERSION $DEBUG ];
27 $VERSION = sprintf "%d.%02d", q$Revision: 1.26 $ =~ /(\d+)\.(\d+)/;
28 $DEBUG = 0 unless defined $DEBUG;
31 use SQL::Translator::Schema::Constants;
32 use SQL::Translator::Utils qw(debug header_comment);
38 varchar2 => 'varchar',
53 my $translator = shift;
54 local $DEBUG = $translator->debug;
55 my $no_comments = $translator->no_comments;
56 my $add_drop_table = $translator->add_drop_table;
57 my $schema = $translator->schema;
59 debug("PKG: Beginning production\n");
62 $create .= header_comment unless ($no_comments);
63 # \todo Don't set if MySQL 3.x is set on command line
64 $create .= "SET foreign_key_checks=0;\n\n";
66 for my $table ( $schema->get_tables ) {
67 my $table_name = $table->name;
68 debug("PKG: Looking at table '$table_name'\n");
71 # Header. Should this look like what mysqldump produces?
73 $create .= "--\n-- Table: $table_name\n--\n" unless $no_comments;
74 $create .= qq[DROP TABLE IF EXISTS $table_name;\n] if $add_drop_table;
75 $create .= "CREATE TABLE $table_name (\n";
81 for my $field ( $table->get_fields ) {
82 my $field_name = $field->name;
83 debug("PKG: Looking at field '$field_name'\n");
84 my $field_def = $field_name;
87 my $data_type = $field->data_type;
88 my @size = $field->size;
89 my %extra = $field->extra;
90 my $list = $extra{'list'} || [];
91 # \todo deal with embedded quotes
92 my $commalist = join( ', ', map { qq['$_'] } @$list );
95 # Oracle "number" type -- figure best MySQL type
97 if ( lc $data_type eq 'number' ) {
99 if ( scalar @size > 1 ) {
100 $data_type = 'double';
102 elsif ( $size[0] >= 12 ) {
103 $data_type = 'bigint';
105 elsif ( $size[0] <= 1 ) {
106 $data_type = 'tinyint';
112 elsif ( exists $translate{ $data_type } ) {
113 $data_type = $translate{ $data_type };
116 $field_def .= " $data_type";
118 if ( lc $data_type eq 'enum' ) {
119 $field_def .= '(' . $commalist . ')';
120 } elsif ( defined $size[0] && $size[0] > 0 ) {
121 $field_def .= '(' . join( ', ', @size ) . ')';
125 for my $qual ( qw[ binary unsigned zerofill ] ) {
126 my $val = $extra{ $qual || uc $qual } or next;
127 $field_def .= " $qual";
131 $field_def .= ' NOT NULL' unless $field->is_nullable;
133 # Default? XXX Need better quoting!
134 my $default = $field->default_value;
135 if ( defined $default ) {
136 if ( uc $default eq 'NULL') {
137 $field_def .= ' DEFAULT NULL';
139 $field_def .= " DEFAULT '$default'";
144 $field_def .= " auto_increment" if $field->is_auto_increment;
145 push @field_defs, $field_def;
152 for my $index ( $table->get_indices ) {
153 push @index_defs, join( ' ',
154 lc $index->type eq 'normal' ? 'INDEX' : $index->type,
156 '(' . join( ', ', $index->fields ) . ')'
161 # Constraints -- need to handle more than just FK. -ky
164 for my $c ( $table->get_constraints ) {
165 my @fields = $c->fields or next;
167 if ( $c->type eq PRIMARY_KEY ) {
168 push @constraint_defs,
169 'PRIMARY KEY (' . join(', ', @fields). ')';
171 elsif ( $c->type eq UNIQUE ) {
172 push @constraint_defs,
173 'UNIQUE (' . join(', ', @fields). ')';
175 elsif ( $c->type eq FOREIGN_KEY ) {
177 map { $_ || () } 'FOREIGN KEY', $c->name
180 $def .= ' (' . join( ', ', @fields ) . ')';
182 $def .= ' REFERENCES ' . $c->reference_table;
184 if ( my @rfields = $c->reference_fields ) {
185 $def .= ' (' . join( ', ', @rfields ) . ')';
188 if ( $c->match_type ) {
190 ( $c->match_type =~ /full/i ) ? 'FULL' : 'PARTIAL';
193 if ( $c->on_delete ) {
194 $def .= ' ON DELETE '.join( ' ', $c->on_delete );
197 if ( $c->on_update ) {
198 $def .= ' ON UPDATE '.join( ' ', $c->on_update );
201 push @constraint_defs, $def;
205 $create .= join(",\n", map { " $_" }
206 @field_defs, @index_defs, @constraint_defs
214 # my ( $key, $val ) = each %{ $table->options }
216 # $create .= " $key=$val"
229 SQL::Translator::Producer::MySQL - MySQL-specific producer for SQL::Translator
233 darren chamberlain E<lt>darren@cpan.orgE<gt>,
234 Ken Y. Clark E<lt>kclark@cpan.orgE<gt>