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