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