- Removed use of $Revision$ SVN keyword to generate VERSION variables; now sub-module...
[dbsrgits/SQL-Translator.git] / lib / SQL / Translator / Producer / DB2.pm
CommitLineData
04bc93b6 1package SQL::Translator::Producer::DB2;
2
3# -------------------------------------------------------------------
821a0fde 4# $Id$
04bc93b6 5# -------------------------------------------------------------------
478f608d 6# Copyright (C) 2002-2009 SQLFairy Authors
04bc93b6 7#
8# This program is free software; you can redistribute it and/or
9# modify it under the terms of the GNU General Public License as
10# published by the Free Software Foundation; version 2.
11#
12# This program is distributed in the hope that it will be useful, but
13# WITHOUT ANY WARRANTY; without even the implied warranty of
14# MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
15# General Public License for more details.
16#
17# You should have received a copy of the GNU General Public License
18# along with this program; if not, write to the Free Software
19# Foundation, Inc., 59 Temple Place, Suite 330, Boston, MA
20# 02111-1307 USA
21# -------------------------------------------------------------------
04bc93b6 22=head1 NAME
23
24SQL::Translator::Producer::DB2 - DB2 SQL producer
25
26=head1 SYNOPSIS
27
28 use SQL::Translator;
29
30 my $t = SQL::Translator->new( parser => '...', producer => 'DB2' );
31 print $translator->translate( $file );
32
33=head1 DESCRIPTION
34
a0ea6c87 35Creates an SQL DDL suitable for DB2.
04bc93b6 36
37=cut
38
a0ea6c87 39use warnings;
04bc93b6 40use strict;
478f608d 41use vars qw[ $DEBUG $WARN ];
04bc93b6 42$DEBUG = 0 unless defined $DEBUG;
43
44use SQL::Translator::Schema::Constants;
45use SQL::Translator::Utils qw(header_comment);
46
47
48# http://publib.boulder.ibm.com/infocenter/db2help/topic/com.ibm.db2.udb.doc/ad/r0006844.htm
49
50# This is a terrible WTDI, each Parser should parse down to some standard set
51# of SQL data types, with field->extra entries being used to convert back to
52# weird types like "polygon" if needed (IMO anyway)
53
3866f0ff 54my %dt_translate;
5e2c196a 55BEGIN {
56 %dt_translate = (
04bc93b6 57 #
58 # MySQL types
59 #
60 int => 'integer',
61 mediumint => 'integer',
62 tinyint => 'smallint',
63 char => 'char',
64 tinyblob => 'blob',
65 mediumblob => 'blob',
66 longblob => 'long varchar for bit data',
67 tinytext => 'varchar',
a0ea6c87 68 text => 'varchar',
69 longtext => 'varchar',
70 mediumtext => 'varchar',
04bc93b6 71 enum => 'varchar',
72 set => 'varchar',
73 date => 'date',
74 datetime => 'timestamp',
75 time => 'time',
76 year => 'date',
77
78 #
79 # PostgreSQL types
80 #
81 'double precision' => 'double',
82 serial => 'integer',
83 bigserial => 'integer',
84 money => 'double',
85 character => 'char',
86 'character varying' => 'varchar',
87 bytea => 'BLOB',
88 interval => 'integer',
89 boolean => 'smallint',
90 point => 'integer',
91 line => 'integer',
92 lseg => 'integer',
93 box => 'integer',
94 path => 'integer',
95 polygon => 'integer',
96 circle => 'integer',
97 cidr => 'integer',
98 inet => 'varchar',
99 macaddr => 'varchar',
100 bit => 'number',
101 'bit varying' => 'number',
102
103 #
104 # DB types
105 #
106 number => 'integer',
107 varchar2 => 'varchar',
108 long => 'clob',
109);
5e2c196a 110}
04bc93b6 111
112my %db2_reserved = map { $_ => 1} qw/
113ADD DETERMINISTIC LEAVE RESTART
114AFTER DISALLOW LEFT RESTRICT
115ALIAS DISCONNECT LIKE RESULT
116ALL DISTINCT LINKTYPE RESULT_SET_LOCATOR
117ALLOCATE DO LOCAL RETURN
118ALLOW DOUBLE LOCALE RETURNS
119ALTER DROP LOCATOR REVOKE
120AND DSNHATTR LOCATORS RIGHT
121ANY DSSIZE LOCK ROLLBACK
122APPLICATION DYNAMIC LOCKMAX ROUTINE
123AS EACH LOCKSIZE ROW
124ASSOCIATE EDITPROC LONG ROWS
125ASUTIME ELSE LOOP RRN
126AUDIT ELSEIF MAXVALUE RUN
127AUTHORIZATION ENCODING MICROSECOND SAVEPOINT
128AUX END MICROSECONDS SCHEMA
129AUXILIARY END-EXEC MINUTE SCRATCHPAD
130BEFORE END-EXEC1 MINUTES SECOND
131BEGIN ERASE MINVALUE SECONDS
132BETWEEN ESCAPE MODE SECQTY
133BINARY EXCEPT MODIFIES SECURITY
134BUFFERPOOL EXCEPTION MONTH SELECT
135BY EXCLUDING MONTHS SENSITIVE
136CACHE EXECUTE NEW SET
137CALL EXISTS NEW_TABLE SIGNAL
138CALLED EXIT NO SIMPLE
139CAPTURE EXTERNAL NOCACHE SOME
140CARDINALITY FENCED NOCYCLE SOURCE
141CASCADED FETCH NODENAME SPECIFIC
142CASE FIELDPROC NODENUMBER SQL
143CAST FILE NOMAXVALUE SQLID
144CCSID FINAL NOMINVALUE STANDARD
145CHAR FOR NOORDER START
146CHARACTER FOREIGN NOT STATIC
147CHECK FREE NULL STAY
148CLOSE FROM NULLS STOGROUP
149CLUSTER FULL NUMPARTS STORES
150COLLECTION FUNCTION OBID STYLE
151COLLID GENERAL OF SUBPAGES
152COLUMN GENERATED OLD SUBSTRING
153COMMENT GET OLD_TABLE SYNONYM
154COMMIT GLOBAL ON SYSFUN
155CONCAT GO OPEN SYSIBM
156CONDITION GOTO OPTIMIZATION SYSPROC
157CONNECT GRANT OPTIMIZE SYSTEM
158CONNECTION GRAPHIC OPTION TABLE
159CONSTRAINT GROUP OR TABLESPACE
160CONTAINS HANDLER ORDER THEN
161CONTINUE HAVING OUT TO
162COUNT HOLD OUTER TRANSACTION
163COUNT_BIG HOUR OVERRIDING TRIGGER
164CREATE HOURS PACKAGE TRIM
165CROSS IDENTITY PARAMETER TYPE
166CURRENT IF PART UNDO
167CURRENT_DATE IMMEDIATE PARTITION UNION
168CURRENT_LC_CTYPE IN PATH UNIQUE
169CURRENT_PATH INCLUDING PIECESIZE UNTIL
170CURRENT_SERVER INCREMENT PLAN UPDATE
171CURRENT_TIME INDEX POSITION USAGE
172CURRENT_TIMESTAMP INDICATOR PRECISION USER
173CURRENT_TIMEZONE INHERIT PREPARE USING
174CURRENT_USER INNER PRIMARY VALIDPROC
175CURSOR INOUT PRIQTY VALUES
176CYCLE INSENSITIVE PRIVILEGES VARIABLE
177DATA INSERT PROCEDURE VARIANT
178DATABASE INTEGRITY PROGRAM VCAT
179DAY INTO PSID VIEW
180DAYS IS QUERYNO VOLUMES
181DB2GENERAL ISOBID READ WHEN
182DB2GENRL ISOLATION READS WHERE
183DB2SQL ITERATE RECOVERY WHILE
184DBINFO JAR REFERENCES WITH
185DECLARE JAVA REFERENCING WLM
186DEFAULT JOIN RELEASE WRITE
187DEFAULTS KEY RENAME YEAR
188DEFINITION LABEL REPEAT YEARS
189DELETE LANGUAGE RESET
190DESCRIPTOR LC_CTYPE RESIGNAL
191/;
192
193#------------------------------------------------------------------------------
194
195sub produce
196{
197 my ($translator) = @_;
198 $DEBUG = $translator->debug;
199 $WARN = $translator->show_warnings;
200 my $no_comments = $translator->no_comments;
201 my $add_drop_table = $translator->add_drop_table;
202 my $schema = $translator->schema;
203 my $output = '';
204 my $indent = ' ';
205
206 $output .= header_comment unless($no_comments);
b08b5416 207 my (@table_defs, @fks, @index_defs);
04bc93b6 208 foreach my $table ($schema->get_tables)
209 {
5e2c196a 210 push @table_defs, 'DROP TABLE ' . $table->name . ";" if $add_drop_table;
b08b5416 211 my ($table_def, $fks) = create_table($table, {
a0ea6c87 212 no_comments => $no_comments});
b08b5416 213 push @table_defs, $table_def;
214 push @fks, @$fks;
04bc93b6 215
a0ea6c87 216 foreach my $index ($table->get_indices)
04bc93b6 217 {
a0ea6c87 218 push @index_defs, create_index($index);
04bc93b6 219 }
a0ea6c87 220
04bc93b6 221 }
a0ea6c87 222 my (@view_defs);
223 foreach my $view ( $schema->get_views )
224 {
225 push @view_defs, create_view($view);
226 }
227 my (@trigger_defs);
228 foreach my $trigger ( $schema->get_triggers )
229 {
230 push @trigger_defs, create_trigger($trigger);
231 }
04bc93b6 232
b08b5416 233 return wantarray ? (@table_defs, @fks, @index_defs, @view_defs, @trigger_defs) :
234 $output . join("\n\n", @table_defs, @fks, @index_defs, @view_defs, @trigger_defs) . "\n";
04bc93b6 235}
236
237{ my %objnames;
238
239 sub check_name
240 {
241 my ($name, $type, $length) = @_;
242
243 my $newname = $name;
244 if(length($name) > $length) ## Maximum table name length is 18
245 {
246 warn "Table name $name is longer than $length characters, truncated" if $WARN;
a0ea6c87 247# if(grep {$_ eq substr($name, 0, $length) }
248# values(%{$objnames{$type}}))
249# {
250# die "Got multiple matching table names when truncated";
251# }
252# $objnames{$type}{$name} = substr($name, 0,$length);
253# $newname = $objnames{$type}{$name};
04bc93b6 254 }
255
256 if($db2_reserved{uc($newname)})
257 {
258 warn "$newname is a reserved word in DB2!" if $WARN;
259 }
260
5e2c196a 261# return sprintf("%-*s", $length-5, $newname);
262 return $newname;
04bc93b6 263 }
264}
265
a0ea6c87 266sub create_table
267{
268 my ($table, $options) = @_;
269
270 my $table_name = check_name($table->name, 'tables', 128);
271 # this limit is 18 in older DB2s ! (<= 8)
272
273 my (@field_defs, @comments);
274 push @comments, "--\n-- Table: $table_name\n--" unless $options->{no_comments};
275 foreach my $field ($table->get_fields)
276 {
277 push @field_defs, create_field($field);
278 }
b08b5416 279 my (@con_defs, @fks);
a0ea6c87 280 foreach my $con ($table->get_constraints)
281 {
b08b5416 282 my ($cdefs, $fks) = create_constraint($con);
283 push @con_defs, @$cdefs;
284 push @fks, @$fks;
a0ea6c87 285 }
a0ea6c87 286
287 my $tablespace = $table->extra()->{'TABLESPACE'} || '';
288 my $table_def = "CREATE TABLE $table_name (\n";
b08b5416 289 $table_def .= join (",\n", map { " $_" } @field_defs, @con_defs);
a0ea6c87 290 $table_def .= "\n)";
291 $table_def .= $tablespace ? "IN $tablespace;" : ';';
292
b08b5416 293 return $table_def, \@fks;
a0ea6c87 294}
295
296sub create_field
297{
298 my ($field) = @_;
299
300 my $field_name = check_name($field->name, 'fields', 30);
301# use Data::Dumper;
302# print Dumper(\%dt_translate);
303# print $field->data_type, " ", $dt_translate{lc($field->data_type)}, "\n";
304 my $data_type = uc($dt_translate{lc($field->data_type)} || $field->data_type);
305 my $size = $field->size();
306
307 my $field_def = "$field_name $data_type";
308 $field_def .= $field->is_auto_increment ?
3866f0ff 309 ' GENERATED BY DEFAULT AS IDENTITY (START WITH 1, INCREMENT BY 1)' : '';
b08b5416 310 $field_def .= $data_type =~ /(CHAR|CLOB)/i ? "(${size})" : '';
a0ea6c87 311 $field_def .= !$field->is_nullable ? ' NOT NULL':'';
312# $field_def .= $field->is_primary_key ? ' PRIMARY KEY':'';
313 $field_def .= !defined $field->default_value ? '' :
314 $field->default_value =~ /current( |_)timestamp/i ||
315 $field->default_value =~ /\Qnow()\E/i ?
b08b5416 316 ' DEFAULT CURRENT TIMESTAMP' : defined $field->default_value ?
317 (" DEFAULT " . ($data_type =~ /(INT|DOUBLE)/i ?
318 $field->default_value : "'" . $field->default_value . "'")
319 ) : '';
a0ea6c87 320
5e2c196a 321 return $field_def;
a0ea6c87 322}
323
324sub create_index
325{
326 my ($index) = @_;
327
328 my $out = sprintf('CREATE %sINDEX %s ON %s ( %s );',
329 $index->type() =~ /^UNIQUE$/i ? 'UNIQUE' : '',
330 $index->name,
331 $index->table->name,
332 join(', ', $index->fields) );
333
334 return $out;
335}
336
337sub create_constraint
338{
339 my ($constraint) = @_;
340
b08b5416 341 my (@con_defs, @fks);
a0ea6c87 342
343 my $ctype = $constraint->type =~ /^PRIMARY(_|\s)KEY$/i ? 'PRIMARY KEY' :
344 $constraint->type =~ /^UNIQUE$/i ? 'UNIQUE' :
345 $constraint->type =~ /^CHECK_C$/i ? 'CHECK' :
b08b5416 346 $constraint->type =~ /^FOREIGN(_|\s)KEY$/i ? 'FOREIGN KEY' : '';
a0ea6c87 347
348 my $expr = $constraint->type =~ /^CHECK_C$/i ? $constraint->expression :
349 '';
b08b5416 350 my $ref = $constraint->type =~ /^FOREIGN(_|\s)KEY$/i ? ('REFERENCES ' . $constraint->reference_table . '(' . join(', ', $constraint->reference_fields) . ')') : '';
a0ea6c87 351 my $update = $constraint->on_update ? $constraint->on_update : '';
352 my $delete = $constraint->on_delete ? $constraint->on_delete : '';
353
b08b5416 354 my $out = join(' ', grep { $_ }
a0ea6c87 355 $constraint->name ? ('CONSTRAINT ' . $constraint->name) : '',
356 $ctype,
357 '(' . join (', ', $constraint->fields) . ')',
358 $expr ? $expr : $ref,
359 $update,
360 $delete);
b08b5416 361 if ($constraint->type eq FOREIGN_KEY) {
362 my $table_name = $constraint->table->name;
363 $out = "ALTER TABLE $table_name ADD $out;";
364 push @fks, $out;
365 }
366 else {
367 push @con_defs, $out;
368 }
a0ea6c87 369
b08b5416 370 return \@con_defs, \@fks;
a0ea6c87 371
372}
373
374sub create_view
375{
376 my ($view) = @_;
377
378 my $out = sprintf("CREATE VIEW %s AS\n%s;",
379 $view->name,
380 $view->sql);
381
382 return $out;
383}
384
385sub create_trigger
386{
387 my ($trigger) = @_;
388# create: CREATE TRIGGER trigger_name before type /ON/i table_name reference_b(?) /FOR EACH ROW/i 'MODE DB2SQL' triggered_action
389
390 my $out = sprintf('CREATE TRIGGER %s %s %s ON %s %s %s MODE DB2SQL %s',
391 $trigger->name,
392 $trigger->perform_action_when || 'AFTER',
393 $trigger->database_event =~ /update_on/i ?
394 ('UPDATE OF '. join(', ', $trigger->fields)) :
395 $trigger->database_event || 'UPDATE',
5e2c196a 396 $trigger->table->name,
a0ea6c87 397 $trigger->extra->{reference} || 'REFERENCING OLD AS oldrow NEW AS newrow',
398 $trigger->extra->{granularity} || 'FOR EACH ROW',
399 $trigger->action );
400
401 return $out;
402
403}
404
405sub alter_field
406{
407 my ($from_field, $to_field) = @_;
5e2c196a 408
409 my $data_type = uc($dt_translate{lc($to_field->data_type)} || $to_field->data_type);
410
411 my $size = $to_field->size();
412 $data_type .= $data_type =~ /CHAR/i ? "(${size})" : '';
413
414 # DB2 will only allow changing of varchar/vargraphic datatypes
415 # to extend their lengths. Or changing of text types to other
416 # texttypes, and numeric types to larger numeric types. (v8)
417 # We can also drop/add keys, checks and constraints, but not
418 # columns !?
419
420 my $out = sprintf('ALTER TABLE %s ALTER %s SET DATATYPE %s',
421 $to_field->table->name,
422 $to_field->name,
423 $data_type);
424
a0ea6c87 425}
426
427sub add_field
428{
5e2c196a 429 my ($new_field) = @_;
430
431 my $out = sprintf('ALTER TABLE %s ADD COLUMN %s',
432 $new_field->table->name,
433 create_field($new_field));
434
435 return $out;
a0ea6c87 436}
437
438sub drop_field
439{
440 my ($field) = @_;
5e2c196a 441
442 return '';
a0ea6c87 443}
04bc93b6 4441;