Added support for MySQL prefix indices (also fixes RT#68735)
[dbsrgits/SQL-Translator.git] / t / 02mysql-parser.t
CommitLineData
0494e672 1#!/usr/bin/perl
2# vim: set ft=perl:
3#
0494e672 4
b8661f30 5use strict;
44fb27ae 6
fbc0552f 7use Test::More;
b8661f30 8use SQL::Translator;
2ab84c11 9use SQL::Translator::Schema::Constants;
5d666b31 10use SQL::Translator::Utils qw//;
2d691ec1 11use Test::SQL::Translator qw(maybe_plan);
d0a4031c 12use FindBin qw/$Bin/;
0494e672 13
2d691ec1 14BEGIN {
c86d295b 15 maybe_plan(347, "SQL::Translator::Parser::MySQL");
fbc0552f 16 SQL::Translator::Parser::MySQL->import('parse');
fbc0552f 17}
18
251b6ff5 19{
20 my $tr = SQL::Translator->new;
6acd7c95 21 my $data = q|create table "sessions" (
2ab84c11 22 id char(32) not null default '0' primary key,
2e8b8523 23 a_session text,
24 ssn varchar(12) unique key,
a383e9e9 25 age int key,
26 fulltext key `session_fulltext` (a_session)
251b6ff5 27 );|;
28
29 my $val = parse($tr, $data);
2ab84c11 30 my $schema = $tr->schema;
e3252059 31 is( $schema->is_valid, 1, 'Schema is valid' );
2ab84c11 32 my @tables = $schema->get_tables;
33 is( scalar @tables, 1, 'Right number of tables (1)' );
34 my $table = shift @tables;
35 is( $table->name, 'sessions', 'Found "sessions" table' );
251b6ff5 36
2ab84c11 37 my @fields = $table->get_fields;
2e8b8523 38 is( scalar @fields, 4, 'Right number of fields (4)' );
2ab84c11 39 my $f1 = shift @fields;
40 my $f2 = shift @fields;
41 is( $f1->name, 'id', 'First field name is "id"' );
42 is( $f1->data_type, 'char', 'Type is "char"' );
43 is( $f1->size, 32, 'Size is "32"' );
44 is( $f1->is_nullable, 0, 'Field cannot be null' );
45 is( $f1->default_value, '0', 'Default value is "0"' );
46 is( $f1->is_primary_key, 1, 'Field is PK' );
251b6ff5 47
2ab84c11 48 is( $f2->name, 'a_session', 'Second field name is "a_session"' );
49 is( $f2->data_type, 'text', 'Type is "text"' );
0c1c8d2a 50 is( $f2->size, 65_535, 'Size is "65,535"' );
2ab84c11 51 is( $f2->is_nullable, 1, 'Field can be null' );
52 is( $f2->default_value, undef, 'Default value is undefined' );
53 is( $f2->is_primary_key, 0, 'Field is not PK' );
251b6ff5 54
2ab84c11 55 my @indices = $table->get_indices;
a383e9e9 56 is( scalar @indices, 2, 'Right number of indices (2)' );
57 my $i = pop @indices;
58 is( $i->type, 'FULLTEXT', 'Found fulltext' );
251b6ff5 59
2ab84c11 60 my @constraints = $table->get_constraints;
2e8b8523 61 is( scalar @constraints, 2, 'Right number of constraints (2)' );
2ab84c11 62 my $c = shift @constraints;
63 is( $c->type, PRIMARY_KEY, 'Constraint is a PK' );
64 is( join(',', $c->fields), 'id', 'Constraint is on "id"' );
2e8b8523 65 my $c2 = shift @constraints;
66 is( $c2->type, UNIQUE, 'Constraint is UNIQUE' );
67 is( join(',', $c2->fields), 'ssn', 'Constraint is on "ssn"' );
251b6ff5 68}
69
70{
71 my $tr = SQL::Translator->new;
aee4b66e 72 my $data = parse($tr,
251b6ff5 73 q[
6acd7c95 74 CREATE TABLE `check` (
aee4b66e 75 check_id int(7) unsigned zerofill NOT NULL default '0000000'
251b6ff5 76 auto_increment primary key,
77 successful date NOT NULL default '0000-00-00',
78 unsuccessful date default '0000-00-00',
79 i1 int(11) default '0' not null,
80 s1 set('a','b','c') default 'b',
bc9932bf 81 e1 enum('a','b','c') default "c",
251b6ff5 82 name varchar(30) default NULL,
83 foo_type enum('vk','ck') NOT NULL default 'vk',
84 date timestamp,
85 time_stamp2 timestamp,
bc9932bf 86 foo_enabled bit(1) default b'0',
87 bar_enabled bit(1) default b"1",
b98bd48d 88 long_foo_enabled bit(10) default b'1010101',
251b6ff5 89 KEY (i1),
62a64f6c 90 UNIQUE (date, i1) USING BTREE,
251b6ff5 91 KEY date_idx (date),
92 KEY name_idx (name(10))
93 ) TYPE=MyISAM PACK_KEYS=1;
94 ]
95 );
aee4b66e 96
2ab84c11 97 my $schema = $tr->schema;
e3252059 98 is( $schema->is_valid, 1, 'Schema is valid' );
2ab84c11 99 my @tables = $schema->get_tables;
100 is( scalar @tables, 1, 'Right number of tables (1)' );
101 my $table = shift @tables;
102 is( $table->name, 'check', 'Found "check" table' );
103
104 my @fields = $table->get_fields;
b98bd48d 105 is( scalar @fields, 13, 'Right number of fields (13)' );
2ab84c11 106 my $f1 = shift @fields;
107 is( $f1->name, 'check_id', 'First field name is "check_id"' );
108 is( $f1->data_type, 'int', 'Type is "int"' );
109 is( $f1->size, 7, 'Size is "7"' );
110 is( $f1->is_nullable, 0, 'Field cannot be null' );
111 is( $f1->default_value, '0000000', 'Default value is "0000000"' );
112 is( $f1->is_primary_key, 1, 'Field is PK' );
113 is( $f1->is_auto_increment, 1, 'Field is auto inc' );
114 my %extra = $f1->extra;
115 ok( defined $extra{'unsigned'}, 'Field is unsigned' );
116 ok( defined $extra{'zerofill'}, 'Field is zerofill' );
117
118 my $f2 = shift @fields;
119 is( $f2->name, 'successful', 'Second field name is "successful"' );
120 is( $f2->data_type, 'date', 'Type is "date"' );
121 is( $f2->size, 0, 'Size is "0"' );
122 is( $f2->is_nullable, 0, 'Field cannot be null' );
123 is( $f2->default_value, '0000-00-00', 'Default value is "0000-00-00"' );
124 is( $f2->is_primary_key, 0, 'Field is not PK' );
125
126 my $f3 = shift @fields;
127 is( $f3->name, 'unsuccessful', 'Third field name is "unsuccessful"' );
128 is( $f3->data_type, 'date', 'Type is "date"' );
129 is( $f3->size, 0, 'Size is "0"' );
130 is( $f3->is_nullable, 1, 'Field can be null' );
131 is( $f3->default_value, '0000-00-00', 'Default value is "0000-00-00"' );
132 is( $f3->is_primary_key, 0, 'Field is not PK' );
133
134 my $f4 = shift @fields;
135 is( $f4->name, 'i1', 'Fourth field name is "i1"' );
136 is( $f4->data_type, 'int', 'Type is "int"' );
137 is( $f4->size, 11, 'Size is "11"' );
138 is( $f4->is_nullable, 0, 'Field cannot be null' );
139 is( $f4->default_value, '0', 'Default value is "0"' );
140 is( $f4->is_primary_key, 0, 'Field is not PK' );
3a0b6f0a 141
2ab84c11 142 my $f5 = shift @fields;
143 is( $f5->name, 's1', 'Fifth field name is "s1"' );
144 is( $f5->data_type, 'set', 'Type is "set"' );
145 is( $f5->size, 1, 'Size is "1"' );
146 is( $f5->is_nullable, 1, 'Field can be null' );
147 is( $f5->default_value, 'b', 'Default value is "b"' );
148 is( $f5->is_primary_key, 0, 'Field is not PK' );
149 my %f5extra = $f5->extra;
150 is( join(',', @{ $f5extra{'list'} || [] }), 'a,b,c', 'List is "a,b,c"' );
3a0b6f0a 151
2ab84c11 152 my $f6 = shift @fields;
153 is( $f6->name, 'e1', 'Sixth field name is "e1"' );
154 is( $f6->data_type, 'enum', 'Type is "enum"' );
155 is( $f6->size, 1, 'Size is "1"' );
156 is( $f6->is_nullable, 1, 'Field can be null' );
157 is( $f6->default_value, 'c', 'Default value is "c"' );
158 is( $f6->is_primary_key, 0, 'Field is not PK' );
159 my %f6extra = $f6->extra;
160 is( join(',', @{ $f6extra{'list'} || [] }), 'a,b,c', 'List is "a,b,c"' );
3a0b6f0a 161
2ab84c11 162 my $f7 = shift @fields;
163 is( $f7->name, 'name', 'Seventh field name is "name"' );
164 is( $f7->data_type, 'varchar', 'Type is "varchar"' );
165 is( $f7->size, 30, 'Size is "30"' );
166 is( $f7->is_nullable, 1, 'Field can be null' );
167 is( $f7->default_value, 'NULL', 'Default value is "NULL"' );
168 is( $f7->is_primary_key, 0, 'Field is not PK' );
3a0b6f0a 169
2ab84c11 170 my $f8 = shift @fields;
171 is( $f8->name, 'foo_type', 'Eighth field name is "foo_type"' );
172 is( $f8->data_type, 'enum', 'Type is "enum"' );
173 is( $f8->size, 2, 'Size is "2"' );
174 is( $f8->is_nullable, 0, 'Field cannot be null' );
175 is( $f8->default_value, 'vk', 'Default value is "vk"' );
176 is( $f8->is_primary_key, 0, 'Field is not PK' );
177 my %f8extra = $f8->extra;
178 is( join(',', @{ $f8extra{'list'} || [] }), 'vk,ck', 'List is "vk,ck"' );
179
180 my $f9 = shift @fields;
181 is( $f9->name, 'date', 'Ninth field name is "date"' );
182 is( $f9->data_type, 'timestamp', 'Type is "timestamp"' );
183 is( $f9->size, 0, 'Size is "0"' );
184 is( $f9->is_nullable, 1, 'Field can be null' );
185 is( $f9->default_value, undef, 'Default value is undefined' );
186 is( $f9->is_primary_key, 0, 'Field is not PK' );
187
188 my $f10 = shift @fields;
189 is( $f10->name, 'time_stamp2', 'Tenth field name is "time_stamp2"' );
190 is( $f10->data_type, 'timestamp', 'Type is "timestamp"' );
191 is( $f10->size, 0, 'Size is "0"' );
192 is( $f10->is_nullable, 1, 'Field can be null' );
193 is( $f10->default_value, undef, 'Default value is undefined' );
194 is( $f10->is_primary_key, 0, 'Field is not PK' );
195
bc9932bf 196 my $f11 = shift @fields;
197 is( $f11->name, 'foo_enabled', 'Eleventh field name is "foo_enabled"' );
198 is( $f11->data_type, 'bit', 'Type is "bit"' );
199 is( $f11->size, 1, 'Size is "1"' );
200 is( $f11->is_nullable, 1, 'Field can be null' );
201 is( $f11->default_value, '0', 'Default value is 0' );
202 is( $f11->is_primary_key, 0, 'Field is not PK' );
203
204 my $f12 = shift @fields;
205 is( $f12->name, 'bar_enabled', 'Twelveth field name is "bar_enabled"' );
206 is( $f12->data_type, 'bit', 'Type is "bit"' );
207 is( $f12->size, 1, 'Size is "1"' );
208 is( $f12->is_nullable, 1, 'Field can be null' );
209 is( $f12->default_value, '1', 'Default value is 1' );
210 is( $f12->is_primary_key, 0, 'Field is not PK' );
b98bd48d 211
212 my $f13 = shift @fields;
213 is( $f13->name, 'long_foo_enabled', 'Thirteenth field name is "long_foo_enabled"' );
214 is( $f13->data_type, 'bit', 'Type is "bit"' );
215 is( $f13->size, 10, 'Size is "10"' );
216 is( $f13->is_nullable, 1, 'Field can be null' );
217 is( $f13->default_value, '1010101', 'Default value is 1010101' );
218 is( $f13->is_primary_key, 0, 'Field is not PK' );
bc9932bf 219
2ab84c11 220 my @indices = $table->get_indices;
221 is( scalar @indices, 3, 'Right number of indices (3)' );
222
223 my $i1 = shift @indices;
224 is( $i1->name, '', 'No name on index' );
225 is( $i1->type, NORMAL, 'Normal index' );
226 is( join(',', $i1->fields ), 'i1', 'Index is on field "i1"' );
227
228 my $i2 = shift @indices;
229 is( $i2->name, 'date_idx', 'Name is "date_idx"' );
230 is( $i2->type, NORMAL, 'Normal index' );
231 is( join(',', $i2->fields ), 'date', 'Index is on field "date"' );
232
233 my $i3 = shift @indices;
234 is( $i3->name, 'name_idx', 'Name is "name_idx"' );
235 is( $i3->type, NORMAL, 'Normal index' );
c86d295b 236 is( join(',', $i3->fields ), 'name', 'Index is on field "name"' );
237 is_deeply( [ $i3->options ], [ { prefix_length => { name => 10 } } ],
238 'Index is on the first 10 chars' );
2ab84c11 239
240 my @constraints = $table->get_constraints;
241 is( scalar @constraints, 2, 'Right number of constraints (2)' );
242
243 my $c1 = shift @constraints;
244 is( $c1->type, PRIMARY_KEY, 'Constraint is a PK' );
245 is( join(',', $c1->fields), 'check_id', 'Constraint is on "check_id"' );
246
247 my $c2 = shift @constraints;
248 is( $c2->type, UNIQUE, 'Constraint is UNIQUE' );
249 is( join(',', $c2->fields), 'date,i1', 'Constraint is on "date, i1"' );
251b6ff5 250}
251
252{
253 my $tr = SQL::Translator->new;
aee4b66e 254 my $data = parse($tr,
251b6ff5 255 q[
256 CREATE TABLE orders (
3a0b6f0a 257 order_id integer NOT NULL auto_increment,
85a6c976 258 member_id varchar(255) comment 'fk to member',
251b6ff5 259 billing_address_id int,
260 shipping_address_id int,
261 credit_card_id int,
262 status smallint NOT NULL,
263 store_id varchar(255) NOT NULL REFERENCES store,
264 tax decimal(8,2),
265 shipping_charge decimal(8,2),
266 price_paid decimal(8,2),
1f5b2625 267 PRIMARY KEY (order_id) USING BTREE,
62a64f6c 268 KEY (status) USING BTREE,
269 KEY USING BTREE (billing_address_id),
251b6ff5 270 KEY (shipping_address_id),
271 KEY (member_id, store_id),
556d0509 272 FOREIGN KEY (status) REFERENCES order_status(id) MATCH FULL ON DELETE CASCADE ON UPDATE CASCADE,
251b6ff5 273 FOREIGN KEY (billing_address_id) REFERENCES address(address_id),
274 FOREIGN KEY (shipping_address_id) REFERENCES address(address_id)
85a6c976 275 ) TYPE=INNODB COMMENT = 'orders table comment';
2ab84c11 276
277 CREATE TABLE address (
278 address_id int NOT NULL auto_increment,
279 recipient varchar(255) NOT NULL,
280 address1 varchar(255) NOT NULL,
281 address2 varchar(255),
282 city varchar(255) NOT NULL,
283 state varchar(255) NOT NULL,
284 postal_code varchar(255) NOT NULL,
285 phone varchar(255),
286 PRIMARY KEY (address_id)
287 ) TYPE=INNODB;
251b6ff5 288 ]
289 ) or die $tr->error;
290
2ab84c11 291 my $schema = $tr->schema;
e3252059 292 is( $schema->is_valid, 1, 'Schema is valid' );
2ab84c11 293 my @tables = $schema->get_tables;
294 is( scalar @tables, 2, 'Right number of tables (2)' );
295
296 my $t1 = shift @tables;
297 is( $t1->name, 'orders', 'Found "orders" table' );
85a6c976 298 is( $t1->comments, 'orders table comment', 'Table comment OK' );
2ab84c11 299
300 my @fields = $t1->get_fields;
301 is( scalar @fields, 10, 'Right number of fields (10)' );
302
303 my $f1 = shift @fields;
304 is( $f1->name, 'order_id', 'First field name is "order_id"' );
305 is( $f1->data_type, 'int', 'Type is "int"' );
306 is( $f1->size, 11, 'Size is "11"' );
307 is( $f1->is_nullable, 0, 'Field cannot be null' );
308 is( $f1->default_value, undef, 'Default value is undefined' );
309 is( $f1->is_primary_key, 1, 'Field is PK' );
310 is( $f1->is_auto_increment, 1, 'Field is auto inc' );
311
312 my $f2 = shift @fields;
313 is( $f2->name, 'member_id', 'Second field name is "member_id"' );
314 is( $f2->data_type, 'varchar', 'Type is "varchar"' );
315 is( $f2->size, 255, 'Size is "255"' );
316 is( $f2->is_nullable, 1, 'Field can be null' );
85a6c976 317 is( $f2->comments, 'fk to member', 'Field comment OK' );
2ab84c11 318 is( $f2->default_value, undef, 'Default value is undefined' );
319
320 my $f3 = shift @fields;
aee4b66e 321 is( $f3->name, 'billing_address_id',
2ab84c11 322 'Third field name is "billing_address_id"' );
323 is( $f3->data_type, 'int', 'Type is "int"' );
324 is( $f3->size, 11, 'Size is "11"' );
325
326 my $f4 = shift @fields;
aee4b66e 327 is( $f4->name, 'shipping_address_id',
2ab84c11 328 'Fourth field name is "shipping_address_id"' );
329 is( $f4->data_type, 'int', 'Type is "int"' );
330 is( $f4->size, 11, 'Size is "11"' );
331
332 my $f5 = shift @fields;
333 is( $f5->name, 'credit_card_id', 'Fifth field name is "credit_card_id"' );
334 is( $f5->data_type, 'int', 'Type is "int"' );
335 is( $f5->size, 11, 'Size is "11"' );
336
337 my $f6 = shift @fields;
338 is( $f6->name, 'status', 'Sixth field name is "status"' );
339 is( $f6->data_type, 'smallint', 'Type is "smallint"' );
340 is( $f6->size, 6, 'Size is "6"' );
341 is( $f6->is_nullable, 0, 'Field cannot be null' );
342
343 my $f7 = shift @fields;
344 is( $f7->name, 'store_id', 'Seventh field name is "store_id"' );
345 is( $f7->data_type, 'varchar', 'Type is "varchar"' );
346 is( $f7->size, 255, 'Size is "255"' );
347 is( $f7->is_nullable, 0, 'Field cannot be null' );
348 is( $f7->is_foreign_key, 1, 'Field is a FK' );
349 my $fk_ref = $f7->foreign_key_reference;
350 isa_ok( $fk_ref, 'SQL::Translator::Schema::Constraint', 'FK' );
351 is( $fk_ref->reference_table, 'store', 'FK is to "store" table' );
352
353 my $f8 = shift @fields;
354 is( $f8->name, 'tax', 'Eighth field name is "tax"' );
355 is( $f8->data_type, 'decimal', 'Type is "decimal"' );
356 is( $f8->size, '8,2', 'Size is "8,2"' );
357
358 my $f9 = shift @fields;
359 is( $f9->name, 'shipping_charge', 'Ninth field name is "shipping_charge"' );
360 is( $f9->data_type, 'decimal', 'Type is "decimal"' );
361 is( $f9->size, '8,2', 'Size is "8,2"' );
362
363 my $f10 = shift @fields;
364 is( $f10->name, 'price_paid', 'Tenth field name is "price_paid"' );
365 is( $f10->data_type, 'decimal', 'Type is "decimal"' );
366 is( $f10->size, '8,2', 'Size is "8,2"' );
367
368 my @indices = $t1->get_indices;
369 is( scalar @indices, 4, 'Right number of indices (4)' );
370
371 my $i1 = shift @indices;
372 is( $i1->type, NORMAL, 'First index is normal' );
373 is( join(',', $i1->fields), 'status', 'Index is on "status"' );
374
375 my $i2 = shift @indices;
376 is( $i2->type, NORMAL, 'Second index is normal' );
aee4b66e 377 is( join(',', $i2->fields), 'billing_address_id',
2ab84c11 378 'Index is on "billing_address_id"' );
379
380 my $i3 = shift @indices;
381 is( $i3->type, NORMAL, 'Third index is normal' );
aee4b66e 382 is( join(',', $i3->fields), 'shipping_address_id',
2ab84c11 383 'Index is on "shipping_address_id"' );
384
385 my $i4 = shift @indices;
386 is( $i4->type, NORMAL, 'Third index is normal' );
aee4b66e 387 is( join(',', $i4->fields), 'member_id,store_id',
2ab84c11 388 'Index is on "member_id,store_id"' );
389
390 my @constraints = $t1->get_constraints;
391 is( scalar @constraints, 5, 'Right number of constraints (5)' );
392
393 my $c1 = shift @constraints;
394 is( $c1->type, PRIMARY_KEY, 'Constraint is a PK' );
395 is( join(',', $c1->fields), 'order_id', 'Constraint is on "order_id"' );
396
397 my $c2 = shift @constraints;
398 is( $c2->type, FOREIGN_KEY, 'Constraint is a FK' );
399 is( join(',', $c2->fields), 'status', 'Constraint is on "status"' );
400 is( $c2->reference_table, 'order_status', 'To table "order_status"' );
401 is( join(',', $c2->reference_fields), 'id', 'To field "id"' );
402
403 my $c3 = shift @constraints;
404 is( $c3->type, FOREIGN_KEY, 'Constraint is a FK' );
aee4b66e 405 is( join(',', $c3->fields), 'billing_address_id',
2ab84c11 406 'Constraint is on "billing_address_id"' );
407 is( $c3->reference_table, 'address', 'To table "address"' );
aee4b66e 408 is( join(',', $c3->reference_fields), 'address_id',
2ab84c11 409 'To field "address_id"' );
410
411 my $c4 = shift @constraints;
412 is( $c4->type, FOREIGN_KEY, 'Constraint is a FK' );
aee4b66e 413 is( join(',', $c4->fields), 'shipping_address_id',
2ab84c11 414 'Constraint is on "shipping_address_id"' );
415 is( $c4->reference_table, 'address', 'To table "address"' );
aee4b66e 416 is( join(',', $c4->reference_fields), 'address_id',
2ab84c11 417 'To field "address_id"' );
418
419 my $c5 = shift @constraints;
420 is( $c5->type, FOREIGN_KEY, 'Constraint is a FK' );
421 is( join(',', $c5->fields), 'store_id', 'Constraint is on "store_id"' );
422 is( $c5->reference_table, 'store', 'To table "store"' );
aee4b66e 423 is( join(',', map { $_ || '' } $c5->reference_fields), '',
c9ca0061 424 'No reference fields defined' );
2ab84c11 425
426 my $t2 = shift @tables;
427 is( $t2->name, 'address', 'Found "address" table' );
428
429 my @t2_fields = $t2->get_fields;
430 is( scalar @t2_fields, 8, 'Right number of fields (8)' );
251b6ff5 431}
13aec984 432
433# djh Tests for:
434# USE database ;
435# ALTER TABLE ADD FOREIGN KEY
436# trailing comma on last create definition
437# Ignoring INSERT statements
438#
439{
440 my $tr = SQL::Translator->new;
aee4b66e 441 my $data = parse($tr,
13aec984 442 q[
443 USE database_name;
444
445 CREATE TABLE one (
446 id integer NOT NULL auto_increment,
447 two_id integer NOT NULL auto_increment,
448 some_data text,
449 PRIMARY KEY (id),
450 INDEX (two_id),
451 ) TYPE=INNODB;
452
453 CREATE TABLE two (
454 id int NOT NULL auto_increment,
455 one_id int NOT NULL auto_increment,
456 some_data text,
457 PRIMARY KEY (id),
458 INDEX (one_id),
459 FOREIGN KEY (one_id) REFERENCES one (id),
460 ) TYPE=INNODB;
461
462 ALTER TABLE one ADD FOREIGN KEY (two_id) REFERENCES two (id);
463
306c3c97 464 INSERT absolutely *#! any old $£ ? rubbish, even "quoted; semi-what""sits";
13aec984 465 ]
466 ) or die $tr->error;
467
468 my $schema = $tr->schema;
469 is( $schema->is_valid, 1, 'Schema is valid' );
470 my $db_name = $schema->name;
471 is( $db_name, 'database_name', 'Database name extracted from USE' );
472 my @tables = $schema->get_tables;
473 is( scalar @tables, 2, 'Right number of tables (2)' );
474 my $table1 = shift @tables;
475 is( $table1->name, 'one', 'Found "one" table' );
476 my $table2 = shift @tables;
477 is( $table2->name, 'two', 'Found "two" table' );
478
479 my @constraints = $table1->get_constraints;
480 is(scalar @constraints, 2, 'Right number of constraints (2) on table one');
481
482 my $t1c1 = shift @constraints;
483 is( $t1c1->type, PRIMARY_KEY, 'Constraint is a PK' );
484 is( join(',', $t1c1->fields), 'id', 'Constraint is on "id"' );
485
486 my $t1c2 = shift @constraints;
487 is( $t1c2->type, FOREIGN_KEY, 'Constraint is a FK' );
488 is( join(',', $t1c2->fields), 'two_id', 'Constraint is on "two_id"' );
489 is( $t1c2->reference_table, 'two', 'To table "two"' );
490 is( join(',', $t1c2->reference_fields), 'id', 'To field "id"' );
491
492 @constraints = $table2->get_constraints;
493 is(scalar @constraints, 2, 'Right number of constraints (2) on table two');
494
495 my $t2c1 = shift @constraints;
496 is( $t2c1->type, PRIMARY_KEY, 'Constraint is a PK' );
497 is( join(',', $t2c1->fields), 'id', 'Constraint is on "id"' );
498
499 my $t2c2 = shift @constraints;
500 is( $t2c2->type, FOREIGN_KEY, 'Constraint is a FK' );
501 is( join(',', $t2c2->fields), 'one_id', 'Constraint is on "one_id"' );
502 is( $t2c2->reference_table, 'one', 'To table "one"' );
503 is( join(',', $t2c2->reference_fields), 'id', 'To field "id"' );
504}
505
b68bfdf0 506# cch Tests for:
507# comments like: /*!40101 SET SQL_MODE=@OLD_SQL_MODE */;
508# char fields with character set and collate qualifiers
509# timestamp fields with on update qualifier
510# charset table option
511#
512{
e6c5fb6e 513 my $tr = SQL::Translator->new(parser_args => {mysql_parser_version => 50013});
aee4b66e 514 my $data = parse($tr,
b68bfdf0 515 q[
aee4b66e 516 DELIMITER ;;
3e5e5622 517 /*!40101 SET SQL_MODE=@OLD_SQL_MODE */;;
aee4b66e 518 /*!50003 CREATE */ /*!50017 DEFINER=`cmdomain`@`localhost` */
519 /*!50003 TRIGGER `acl_entry_insert` BEFORE INSERT ON `acl_entry`
520 FOR EACH ROW SET NEW.dateCreated = CONVERT_TZ(SYSDATE(),'SYSTEM','+0:00'),
521 NEW.dateModified = CONVERT_TZ(SYSDATE(),'SYSTEM','+0:00') */;;
b68bfdf0 522
aee4b66e 523 DELIMITER ;
b68bfdf0 524 CREATE TABLE one (
525 `op` varchar(255) character set latin1 collate latin1_bin default NULL,
0a2833d8 526 `last_modified` timestamp NOT NULL default Current_Timestamp on update CURRENT_TIMESTAMP,
527 `created_at` datetime NOT NULL Default CURRENT_TIMESTAMP(),
b68bfdf0 528 ) TYPE=INNODB DEFAULT CHARSET=latin1;
d31c185b 529
aee4b66e 530 /*!50001 CREATE ALGORITHM=UNDEFINED */
531 /*!50013 DEFINER=`cmdomain`@`localhost` SQL SECURITY DEFINER */
e6c5fb6e 532 /*!50014 DEFINER=`BOGUS` */
aee4b66e 533 /*! VIEW `vs_asset` AS
534 select `a`.`asset_id` AS `asset_id`,`a`.`fq_name` AS `fq_name`,
535 `cfgmgmt_mig`.`ap_extract_folder`(`a`.`fq_name`) AS `folder_name`,
536 `cfgmgmt_mig`.`ap_extract_asset`(`a`.`fq_name`) AS `asset_name`,
537 `a`.`annotation` AS `annotation`,`a`.`asset_type` AS `asset_type`,
538 `a`.`foreign_asset_id` AS `foreign_asset_id`,
539 `a`.`foreign_asset_id2` AS `foreign_asset_id2`,`a`.`dateCreated` AS `date_created`,
540 `a`.`dateModified` AS `date_modified`,`a`.`container_id` AS `container_id`,
541 `a`.`creator_id` AS `creator_id`,`a`.`modifier_id` AS `modifier_id`,
542 `m`.`user_id` AS `user_access`
543 from (`asset` `a` join `M_ACCESS_CONTROL` `m` on((`a`.`acl_id` = `m`.`acl_id`))) */;
544 DELIMITER ;;
545 /*!50001 CREATE */
546 /*! VIEW `vs_asset2` AS
547 select `a`.`asset_id` AS `asset_id`,`a`.`fq_name` AS `fq_name`,
548 `cfgmgmt_mig`.`ap_extract_folder`(`a`.`fq_name`) AS `folder_name`,
549 `cfgmgmt_mig`.`ap_extract_asset`(`a`.`fq_name`) AS `asset_name`,
550 `a`.`annotation` AS `annotation`,`a`.`asset_type` AS `asset_type`,
551 `a`.`foreign_asset_id` AS `foreign_asset_id`,
552 `a`.`foreign_asset_id2` AS `foreign_asset_id2`,`a`.`dateCreated` AS `date_created`,
553 `a`.`dateModified` AS `date_modified`,`a`.`container_id` AS `container_id`,
554 `a`.`creator_id` AS `creator_id`,`a`.`modifier_id` AS `modifier_id`,
555 `m`.`user_id` AS `user_access`
556 from (`asset` `a` join `M_ACCESS_CONTROL` `m` on((`a`.`acl_id` = `m`.`acl_id`))) */;
557 DELIMITER ;;
558 /*!50001 CREATE OR REPLACE */
559 /*! VIEW `vs_asset3` AS
560 select `a`.`asset_id` AS `asset_id`,`a`.`fq_name` AS `fq_name`,
561 `cfgmgmt_mig`.`ap_extract_folder`(`a`.`fq_name`) AS `folder_name`,
562 `cfgmgmt_mig`.`ap_extract_asset`(`a`.`fq_name`) AS `asset_name`,
563 `a`.`annotation` AS `annotation`,`a`.`asset_type` AS `asset_type`,
564 `a`.`foreign_asset_id` AS `foreign_asset_id`,
565 `a`.`foreign_asset_id2` AS `foreign_asset_id2`,`a`.`dateCreated` AS `date_created`,
566 `a`.`dateModified` AS `date_modified`,`a`.`container_id` AS `container_id`,
567 `a`.`creator_id` AS `creator_id`,`a`.`modifier_id` AS `modifier_id`,
568 `m`.`user_id` AS `user_access`
569 from (`asset` `a` join `M_ACCESS_CONTROL` `m` on((`a`.`acl_id` = `m`.`acl_id`))) */;
570 DELIMITER ;;
571 /*!50003 CREATE*/ /*!50020 DEFINER=`cmdomain`@`localhost`*/ /*!50003 FUNCTION `ap_from_millitime_nullable`( millis_since_1970 BIGINT ) RETURNS timestamp
572 DETERMINISTIC
573 BEGIN
574 DECLARE rval TIMESTAMP;
575 IF ( millis_since_1970 = 0 )
576 THEN
577 SET rval = NULL;
578 ELSE
579 SET rval = FROM_UNIXTIME( millis_since_1970 / 1000 );
580 END IF;
581 RETURN rval;
582 END */;;
583 /*!50003 CREATE*/ /*!50020 DEFINER=`cmdomain`@`localhost`*/ /*!50003 PROCEDURE `sp_update_security_acl`(IN t_acl_id INTEGER)
584 BEGIN
585 DECLARE hasMoreRows BOOL DEFAULT TRUE;
586 DECLARE t_group_id INT;
587 DECLARE t_user_id INT ;
588 DECLARE t_user_name VARCHAR (512) ;
589 DECLARE t_message VARCHAR (512) ;
590
591 DROP TABLE IF EXISTS group_acl;
592 DROP TABLE IF EXISTS user_group;
593 DELETE FROM M_ACCESS_CONTROL WHERE acl_id = t_acl_id;
594
595 CREATE TEMPORARY TABLE group_acl SELECT DISTINCT p.id group_id, d.acl_id acl_id
596 FROM asset d, acl_entry e, alterpoint_principal p
597 WHERE d.acl_id = e.acl
598 AND p.id = e.principal AND d.acl_id = t_acl_id;
599
600 CREATE TEMPORARY TABLE user_group SELECT a.id user_id, a.name user_name, c.id group_id
601 FROM alterpoint_principal a, groups_for_user b, alterpoint_principal c
602 WHERE a.id = b.user_ref AND b.elt = c.id;
603
604 INSERT INTO M_ACCESS_CONTROL SELECT DISTINCT group_acl.group_id, group_acl.acl_id, user_group.user_id, user_group.user_name
605 FROM group_acl, user_group
606 WHERE group_acl.group_id = user_group.group_id ;
607 END */;;
b68bfdf0 608 ]
609 ) or die $tr->error;
610
611 my $schema = $tr->schema;
612 is( $schema->is_valid, 1, 'Schema is valid' );
613 my @tables = $schema->get_tables;
614 is( scalar @tables, 1, 'Right number of tables (1)' );
615 my $table1 = shift @tables;
616 is( $table1->name, 'one', 'Found "one" table' );
617
618 my @fields = $table1->get_fields;
0a2833d8 619 is(scalar @fields, 3, 'Right number of fields (3) on table one');
b68bfdf0 620 my $tableTypeFound = 0;
621 my $charsetFound = 0;
aee4b66e 622 for my $t1_option_ref ( $table1->options ) {
623 my($key, $value) = %{$t1_option_ref};
624 if ( $key eq 'TYPE' ) {
625 is($value, 'INNODB', 'Table has right table type option' );
626 $tableTypeFound = 1;
627 } elsif ( $key eq 'CHARACTER SET' ) {
628 is($value, 'latin1', 'Table has right character set option' );
629 $charsetFound = 1;
630 }
631 }
632 fail('Table did not have a type option') unless $tableTypeFound;
633 fail('Table did not have a character set option') unless $charsetFound;
b68bfdf0 634
635 my $t1f1 = shift @fields;
636 is( $t1f1->data_type, 'varchar', 'Field is a varchar' );
637 is( $t1f1->size, 255, 'Field is right size' );
638 is( $t1f1->extra('character set'), 'latin1', 'Field has right character set qualifier' );
639 is( $t1f1->extra('collate'), 'latin1_bin', 'Field has right collate qualifier' );
640 is( $t1f1->default_value, 'NULL', 'Field has right default value' );
641
642 my $t1f2 = shift @fields;
643 is( $t1f2->data_type, 'timestamp', 'Field is a timestamp' );
644 ok( !$t1f2->is_nullable, 'Field is not nullable' );
6d80a120 645 is_deeply(
646 $t1f2->default_value,
647 \'CURRENT_TIMESTAMP',
aee4b66e 648 'Field has right default value'
6d80a120 649 );
0a2833d8 650 is_deeply( $t1f2->extra('on update'), \'CURRENT_TIMESTAMP', 'Field has right on update qualifier' );
651
652 my $t1f3 = shift @fields;
653 is( $t1f3->data_type, 'datetime', 'Field is a datetime' );
654 ok( !$t1f3->is_nullable, 'Field is not nullable' );
655 is_deeply(
656 $t1f3->default_value,
657 \'CURRENT_TIMESTAMP',
658 'Field has right default value'
659 );
3ebe2ce5 660
d31c185b 661 my @views = $schema->get_views;
22b9814a 662 is( scalar @views, 3, 'Right number of views (3)' );
3ebe2ce5 663
664 my ($view1, $view2, $view3) = @views;
d31c185b 665 is( $view1->name, 'vs_asset', 'Found "vs_asset" view' );
22b9814a 666 is( $view2->name, 'vs_asset2', 'Found "vs_asset2" view' );
667 is( $view3->name, 'vs_asset3', 'Found "vs_asset3" view' );
3ebe2ce5 668 like($view1->sql, qr/vs_asset/, "Detected view vs_asset");
aa4301a7 669
670 # KYC - commenting this out as I don't understand why this string
671 # should /not/ be detected when it is in the SQL - 2/28/12
672 # like($view1->sql, qr/cfgmgmt_mig/, "Did not detect cfgmgmt_mig");
673
674 is( join(',', $view1->fields),
675 join(',', qw[ asset_id fq_name folder_name asset_name annotation
676 asset_type foreign_asset_id foreign_asset_id2 date_created
677 date_modified container_id creator_id modifier_id user_access
678 ] ),
679 'First view has correct fields'
680 );
3ebe2ce5 681
e6c5fb6e 682 my @options = $view1->options;
683
684 is_deeply(
685 \@options,
686 [
687 'ALGORITHM=UNDEFINED',
688 'DEFINER=`cmdomain`@`localhost`',
689 'SQL SECURITY DEFINER',
690 ],
691 'Only version 50013 options parsed',
692 );
693
d31c185b 694 my @procs = $schema->get_procedures;
695 is( scalar @procs, 2, 'Right number of procedures (2)' );
696 my $proc1 = shift @procs;
697 is( $proc1->name, 'ap_from_millitime_nullable', 'Found "ap_from_millitime_nullable" procedure' );
aee4b66e 698 like($proc1->sql, qr/CREATE FUNCTION ap_from_millitime_nullable/, "Detected procedure ap_from_millitime_nullable");
d31c185b 699 my $proc2 = shift @procs;
700 is( $proc2->name, 'sp_update_security_acl', 'Found "sp_update_security_acl" procedure' );
aee4b66e 701 like($proc2->sql, qr/CREATE PROCEDURE sp_update_security_acl/, "Detected procedure sp_update_security_acl");
b68bfdf0 702}
703
a7f49dfb 704# Tests for collate table option
705{
706 my $tr = SQL::Translator->new(parser_args => {mysql_parser_version => 50003});
aee4b66e 707 my $data = parse($tr,
a7f49dfb 708 q[
bb4c66d1 709 CREATE TABLE test ( id int ) DEFAULT CHARACTER SET latin1 COLLATE latin1_bin;
aee4b66e 710 ] );
4d438549 711
a7f49dfb 712 my $schema = $tr->schema;
713 is( $schema->is_valid, 1, 'Schema is valid' );
714 my @tables = $schema->get_tables;
715 is( scalar @tables, 1, 'Right number of tables (1)' );
716 my $table1 = shift @tables;
717 is( $table1->name, 'test', 'Found "test" table' );
718
719
720 my $collate = "Not found!";
bb4c66d1 721 my $charset = "Not found!";
a7f49dfb 722 for my $t1_option_ref ( $table1->options ) {
723 my($key, $value) = %{$t1_option_ref};
bb4c66d1 724 $collate = $value if $key eq 'COLLATE';
725 $charset = $value if $key eq 'CHARACTER SET';
a7f49dfb 726 }
727 is($collate, 'latin1_bin', "Collate found");
bb4c66d1 728 is($charset, 'latin1', "Character set found");
a7f49dfb 729}
5d666b31 730
731# Test the mysql version parser (probably needs to migrate to t/utils.t)
732my $parse_as = {
733 perl => {
734 '3.23.2' => 3.023002,
735 '4' => 4.000000,
736 '50003' => 5.000003,
737 '5.01.0' => 5.001000,
738 '5.1' => 5.001000,
739 },
740 mysql => {
741 '3.23.2' => 32302,
742 '4' => 40000,
743 '50003' => 50003,
744 '5.01.0' => 50100,
745 '5.1' => 50100,
746 },
747};
748
749for my $target (keys %$parse_as) {
750 for my $str (keys %{$parse_as->{$target}}) {
751 cmp_ok (
752 SQL::Translator::Utils::parse_mysql_version ($str, $target),
753 '==',
754 $parse_as->{$target}{$str},
755 "'$str' parsed as $target version '$parse_as->{$target}{$str}'",
756 );
757 }
758}
759
760eval { SQL::Translator::Utils::parse_mysql_version ('bogus5.1') };
761ok ($@, 'Exception thrown on invalid version string');
9a96648f 762
763{
764 my $tr = SQL::Translator->new;
765 my $data = q|create table merge_example (
766 id int(11) NOT NULL auto_increment,
767 shape_field geometry NOT NULL,
768 PRIMARY KEY (id),
769 SPATIAL KEY shape_field (shape_field)
770 ) ENGINE=MRG_MyISAM UNION=(`sometable_0`,`sometable_1`,`sometable_2`);|;
771
772 my $val = parse($tr, $data);
773 my $schema = $tr->schema;
774 is( $schema->is_valid, 1, 'Schema is valid' );
775 my @tables = $schema->get_tables;
776 is( scalar @tables, 1, 'Right number of tables (1)' );
777 my $table = shift @tables;
778 is( $table->name, 'merge_example', 'Found "merge_example" table' );
779
780 my $tableTypeFound = 0;
781 my $unionFound = 0;
782 for my $t_option_ref ( $table->options ) {
783 my($key, $value) = %{$t_option_ref};
784 if ( $key eq 'ENGINE' ) {
785 is($value, 'MRG_MyISAM', 'Table has right table engine option' );
786 $tableTypeFound = 1;
787 } elsif ( $key eq 'UNION' ) {
788 is_deeply($value, [ 'sometable_0','sometable_1','sometable_2' ],
789 "UNION option has correct set");
790 $unionFound = 1;
791 }
792 }
793
794 fail('Table did not have a type option') unless $tableTypeFound;
795 fail('Table did not have a union option') unless $unionFound;
796
797 my @fields = $table->get_fields;
798 is( scalar @fields, 2, 'Right number of fields (2)' );
799 my $f1 = shift @fields;
800 my $f2 = shift @fields;
801 is( $f1->name, 'id', 'First field name is "id"' );
802 is( $f1->data_type, 'int', 'Type is "int"' );
803 is( $f1->size, 11, 'Size is "11"' );
804 is( $f1->is_nullable, 0, 'Field cannot be null' );
805 is( $f1->is_primary_key, 1, 'Field is PK' );
806
807 is( $f2->name, 'shape_field', 'Second field name is "shape_field"' );
808 is( $f2->data_type, 'geometry', 'Type is "geometry"' );
809 is( $f2->is_nullable, 0, 'Field cannot be null' );
810 is( $f2->is_primary_key, 0, 'Field is not PK' );
811
812 my @indices = $table->get_indices;
813 is( scalar @indices, 1, 'Right number of indices (1)' );
814 my $i1 = shift @indices;
815 is( $i1->name, 'shape_field', 'No name on index' );
816 is( $i1->type, SPATIAL, 'Spatial index' );
817
818 my @constraints = $table->get_constraints;
819 is( scalar @constraints, 1, 'Right number of constraints (1)' );
820 my $c = shift @constraints;
821 is( $c->type, PRIMARY_KEY, 'Constraint is a PK' );
822 is( join(',', $c->fields), 'id', 'Constraint is on "id"' );
823}
47666977 824
825{
826 my @data = (
827 q|create table quote (
828 id int(11) NOT NULL auto_increment,
829 PRIMARY KEY (id)
830 ) ENGINE="innodb";|,
831 q|create table quote (
832 id int(11) NOT NULL auto_increment,
833 PRIMARY KEY (id)
834 ) ENGINE='innodb';|,
835 q|create table quote (
836 id int(11) NOT NULL auto_increment,
837 PRIMARY KEY (id)
838 ) ENGINE=innodb;|,
839 );
840 for my $data (@data) {
841 my $tr = SQL::Translator->new;
842
843 my $val = parse($tr, $data);
844 my $schema = $tr->schema;
845 is( $schema->is_valid, 1, 'Schema is valid' );
846 my @tables = $schema->get_tables;
847 is( scalar @tables, 1, 'Right number of tables (1)' );
848 my $table = shift @tables;
849 is( $table->name, 'quote', 'Found "quote" table' );
850
851 my $tableTypeFound = 0;
852 for my $t_option_ref ( $table->options ) {
853 my($key, $value) = %{$t_option_ref};
854 if ( $key eq 'ENGINE' ) {
855 is($value, 'innodb', 'Table has right table engine option' );
856 $tableTypeFound = 1;
857 }
858 }
859
860 fail('Table did not have a type option') unless $tableTypeFound;
861
862 my @fields = $table->get_fields;
863 my $f1 = shift @fields;
864 is( $f1->name, 'id', 'First field name is "id"' );
865 is( $f1->data_type, 'int', 'Type is "int"' );
866 is( $f1->size, 11, 'Size is "11"' );
867 is( $f1->is_nullable, 0, 'Field cannot be null' );
868 is( $f1->is_primary_key, 1, 'Field is PK' );
869 }
870}
871
8b075c9f 872{
873 my $tr = SQL::Translator->new;
874 my $data = q|create table "sessions" (
875 id char(32) not null default '0' primary key,
876 ssn varchar(12) NOT NULL default 'test single quotes like in you''re',
877 user varchar(20) NOT NULL default 'test single quotes escaped like you\'re',
34248db8 878 key using btree (ssn)
8b075c9f 879 );|;
880
881 my $val = parse($tr, $data);
882 my $schema = $tr->schema;
883 is( $schema->is_valid, 1, 'Schema is valid' );
884 my @tables = $schema->get_tables;
885 is( scalar @tables, 1, 'Right number of tables (1)' );
886 my $table = shift @tables;
887 is( $table->name, 'sessions', 'Found "sessions" table' );
888
889 my @fields = $table->get_fields;
890 is( scalar @fields, 3, 'Right number of fields (3)' );
891 my $f1 = shift @fields;
892 my $f2 = shift @fields;
893 my $f3 = shift @fields;
894 is( $f1->name, 'id', 'First field name is "id"' );
895 is( $f1->data_type, 'char', 'Type is "char"' );
896 is( $f1->size, 32, 'Size is "32"' );
897 is( $f1->is_nullable, 0, 'Field cannot be null' );
898 is( $f1->default_value, '0', 'Default value is "0"' );
899 is( $f1->is_primary_key, 1, 'Field is PK' );
900
901 is( $f2->name, 'ssn', 'Second field name is "ssn"' );
902 is( $f2->data_type, 'varchar', 'Type is "varchar"' );
903 is( $f2->size, 12, 'Size is "12"' );
904 is( $f2->is_nullable, 0, 'Field can not be null' );
905 is( $f2->default_value, "test single quotes like in you''re", "Single quote in default value is escaped properly" );
906 is( $f2->is_primary_key, 0, 'Field is not PK' );
907
908 # this is more of a sanity test because the original sqlt regex for default looked for an escaped quote represented as \'
aee4b66e 909 # however in mysql 5.x (and probably other previous versions) still actually outputs that as ''
8b075c9f 910 is( $f3->name, 'user', 'Second field name is "user"' );
911 is( $f3->data_type, 'varchar', 'Type is "varchar"' );
912 is( $f3->size, 20, 'Size is "20"' );
913 is( $f3->is_nullable, 0, 'Field can not be null' );
914 is( $f3->default_value, "test single quotes escaped like you\\'re", "Single quote in default value is escaped properly" );
915 is( $f3->is_primary_key, 0, 'Field is not PK' );
916}
34248db8 917
918{
919 # silence PR::D from spewing on STDERR
bdf60588 920 local $::RD_ERRORS = 0;
921 local $::RD_WARN = 0;
922 local $::RD_HINT = 0;
34248db8 923 my $tr = SQL::Translator->new;
924 my $data = q|create table "sessions" (
925 id char(32) not null default,
926 ssn varchar(12) NOT NULL default 'test single quotes like in you''re',
927 user varchar(20) NOT NULL default 'test single quotes escaped like you\'re',
928 key using btree (ssn)
929 );|;
930
931 my $val= parse($tr,$data);
932 ok ($tr->error =~ /Parse failed\./, 'Parse failed error without default value');
933}
934
935{
936 # make sure empty string default value still works
937 my $tr = SQL::Translator->new;
938 my $data = q|create table "sessions" (
939 id char(32) not null DEFAULT '',
940 ssn varchar(12) NOT NULL default "",
941 key using btree (ssn)
942 );|;
943 my $val= parse($tr,$data);
944
945 my @fields = $tr->schema->get_table('sessions')->get_fields;
946 is (scalar @fields, 2, 'Both fields parsed correctly');
947 for (@fields) {
948 my $def = $_->default_value;
949 ok( (defined $def and $def eq ''), "Defaults on field $_ correct" );
950 }
951}
d0a4031c 952
953{
954 # test rt70437 and rt71468
955 my $file = "$Bin/data/mysql/cashmusic_db.sql";
956 ok (-f $file,"File exists");
957 my $tr = SQL::Translator->new( parser => 'MySQL');
958 ok ($tr->translate($file),'File translated');
959 ok (!$tr->error, 'no error');
960 ok (my $schema = $tr->schema, 'got schema');
961}