8 use DBIx::Class::Optional::Dependencies ();
11 use DBIC::DebugObj ();
12 use DBIC::SqlMakerTest;
14 my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_MSACCESS_ODBC_${_}" } qw/DSN USER PASS/};
15 my ($dsn2, $user2, $pass2) = @ENV{map { "DBICTEST_MSACCESS_ADO_${_}" } qw/DSN USER PASS/};
17 plan skip_all => 'Test needs ' .
18 (join ' or ', map { $_ ? $_ : () }
19 DBIx::Class::Optional::Dependencies->req_missing_for('test_rdbms_msaccess_odbc'),
20 DBIx::Class::Optional::Dependencies->req_missing_for('test_rdbms_msaccess_ado'))
22 $dsn && DBIx::Class::Optional::Dependencies->req_ok_for('test_rdbms_msaccess_odbc')
24 $dsn2 && DBIx::Class::Optional::Dependencies->req_ok_for('test_rdbms_msaccess_ado')
28 DBICTest::Schema->load_classes('ArtistGUID');
30 # Example DSNs (32bit only):
31 # dbi:ODBC:driver={Microsoft Access Driver (*.mdb, *.accdb)};dbq=C:\Users\rkitover\Documents\access_sample.accdb
32 # dbi:ADO:Microsoft.Jet.OLEDB.4.0;Data Source=C:\Users\rkitover\Documents\access_sample.accdb
33 # dbi:ADO:Provider=Microsoft.ACE.OLEDB.12.0;Data Source=C:\Users\rkitover\Documents\access_sample.accdb;Persist Security Info=False'
35 plan skip_all => <<'EOF' unless $dsn || $dsn2;
36 Set $ENV{DBICTEST_MSACCESS_ODBC_DSN} and/or $ENV{DBICTEST_MSACCESS_ADO_DSN} (and optionally _USER and _PASS) to run these tests.
37 Warning: this test drops and creates the tables 'artist', 'cd', 'bindtype_test' and 'artist_guid'.
41 [ $dsn, $user || '', $pass || '' ],
42 [ $dsn2, $user2 || '', $pass2 || '' ],
45 foreach my $info (@info) {
46 my ($dsn, $user, $pass) = @$info;
50 # Check that we can connect without any options.
51 my $schema = DBICTest::Schema->connect($dsn, $user, $pass);
53 $schema->storage->ensure_connected;
54 } 'connection without any options';
56 my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
57 $binstr{'large'} = $binstr{'small'} x 1024;
59 my $maxloblen = length $binstr{'large'};
61 $schema = DBICTest::Schema->connect($dsn, $user, $pass, {
64 LongReadLen => $maxloblen,
67 my $guard = Scope::Guard->new(sub { cleanup($schema) });
69 my $dbh = $schema->storage->dbh;
71 # turn off warnings for OLE exception from ADO about nonexistant table
72 eval { local $^W = 0; $dbh->do("DROP TABLE artist") };
76 artistid AUTOINCREMENT PRIMARY KEY,
77 name VARCHAR(255) NULL,
78 charfield CHAR(10) NULL,
83 my $ars = $schema->resultset('Artist');
84 is ( $ars->count, 0, 'No rows at first' );
86 # test primary key handling
87 my $new = $ars->create({ name => 'foo' });
88 ok($new->artistid, "Auto-PK worked");
90 my $first_artistid = $new->artistid;
92 # test explicit key spec
93 $new = $ars->create ({ name => 'bar', artistid => 66 });
94 is($new->artistid, 66, 'Explicit PK worked');
95 $new->discard_changes;
96 is($new->artistid, 66, 'Explicit PK assigned');
99 eval { local $^W = 0; $dbh->do("DROP TABLE cd") };
103 cdid AUTOINCREMENT PRIMARY KEY,
105 title VARCHAR(255) NULL,
107 genreid INTEGER NULL,
108 single_track INTEGER NULL
114 trackid AUTOINCREMENT PRIMARY KEY,
115 cd INTEGER REFERENCES cd(cdid),
118 last_updated_on DATETIME,
119 last_updated_at DATETIME
123 my $cd = $schema->resultset('CD')->create({
124 artist => $first_artistid,
125 title => 'Some Album',
129 my $joined_artist = $schema->resultset('Artist')->search({
130 artistid => $first_artistid,
133 '+select' => [ 'cds.title' ],
134 '+as' => [ 'cd_title' ],
137 is $joined_artist->get_column('cd_title'), 'Some Album',
138 'one-step join works';
141 my $track = $schema->resultset('Track')->create({
149 my $joined_track = try {
150 local $schema->storage->{debug} = 1;
151 local $schema->storage->{debugobj} = DBIC::DebugObj->new(\$sql, \@bind);
153 $schema->resultset('Artist')->search({
154 artistid => $first_artistid,
156 join => [{ cds => 'tracks' }],
157 '+select' => [ 'tracks.title' ],
158 '+as' => [ 'track_title' ],
162 diag "Could not execute two-step left join: $_";
165 s/^'//, s/'\z// for @bind;
167 # test is duplicated in t/sqlmaker/msaccess.t, keep a duplicate here anyway, just to be safe
172 'SELECT [me].[artistid], [me].[name], [me].[rank], [me].[charfield], [tracks].[title] FROM ( ( [artist] [me] LEFT JOIN cd [cds] ON [cds].[artist] = [me].[artistid] ) LEFT JOIN [track] [tracks] ON [tracks].[cd] = [cds].[cdid] ) WHERE ( [artistid] = ? )',
174 'correct SQL for two-step left join',
177 is try { $joined_track->get_column('track_title') }, 'my track',
178 'two-step left join works';
182 $joined_artist = try {
183 local $schema->storage->{debug} = 1;
184 local $schema->storage->{debugobj} = DBIC::DebugObj->new(\$sql, \@bind);
186 $schema->resultset('Track')->search({
187 trackid => $track->trackid,
189 join => [{ cd => 'artist' }],
190 '+select' => [ 'artist.name' ],
191 '+as' => [ 'artist_name' ],
195 diag "Could not execute two-step inner join: $_";
198 s/^'//, s/'\z// for @bind;
200 # test is duplicated in t/sqlmaker/msaccess.t, keep a duplicate here anyway, just to be safe
205 'SELECT [me].[trackid], [me].[cd], [me].[position], [me].[title], [me].[last_updated_on], [me].[last_updated_at], [artist].[name] FROM ( ( [track] [me] INNER JOIN cd [cd] ON [cd].[cdid] = [me].[cd] ) INNER JOIN [artist] [artist] ON [artist].[artistid] = [cd].[artist] ) WHERE ( [trackid] = ? )',
207 'correct SQL for two-step inner join',
210 is try { $joined_artist->get_column('artist_name') }, 'foo',
211 'two-step inner join works';
213 # test basic transactions
214 $schema->txn_do(sub {
215 $ars->create({ name => 'transaction_commit' });
217 ok($ars->search({ name => 'transaction_commit' })->first,
218 'transaction committed');
219 $ars->search({ name => 'transaction_commit' })->delete,
221 $schema->txn_do(sub {
222 $ars->create({ name => 'transaction_rollback' });
225 } qr/rolling back/, 'rollback executed';
226 is $ars->search({ name => 'transaction_rollback' })->first, undef,
227 'transaction rolled back';
229 # test two-phase commit and inner transaction rollback from nested transactions
230 $schema->txn_do(sub {
231 $ars->create({ name => 'in_outer_transaction' });
232 $schema->txn_do(sub {
233 $ars->create({ name => 'in_inner_transaction' });
235 ok($ars->search({ name => 'in_inner_transaction' })->first,
236 'commit from inner transaction visible in outer transaction');
238 $schema->txn_do(sub {
239 $ars->create({ name => 'in_inner_transaction_rolling_back' });
240 die 'rolling back inner transaction';
242 } qr/rolling back inner transaction/, 'inner transaction rollback executed';
244 ok($ars->search({ name => 'in_outer_transaction' })->first,
245 'commit from outer transaction');
246 ok($ars->search({ name => 'in_inner_transaction' })->first,
247 'commit from inner transaction');
248 is $ars->search({ name => 'in_inner_transaction_rolling_back' })->first,
250 'rollback from inner transaction';
251 $ars->search({ name => 'in_outer_transaction' })->delete;
252 $ars->search({ name => 'in_inner_transaction' })->delete;
258 push @pop, { name => "Artist_$_" };
260 $ars->populate (\@pop);
263 # test populate with explicit key
267 push @pop, { name => "Artist_expkey_$_", artistid => 100 + $_ };
269 $ars->populate (\@pop);
272 # count what we did so far
273 is ($ars->count, 6, 'Simple count works');
276 # not testing offset because access only supports TOP
277 my $lim = $ars->search( {},
281 order_by => 'artistid'
284 is( $lim->count, 2, 'ROWS+OFFSET count ok' );
285 is( $lim->all, 2, 'Number of ->all objects matches count' );
289 is( $lim->next->artistid, 1, "iterator->next ok" );
290 is( $lim->next->artistid, 66, "iterator->next ok" );
291 is( $lim->next, undef, "next past end of resultset ok" );
294 my $current_artistid = $ars->search({}, {
295 select => [ { max => 'artistid' } ], as => ['artistid']
299 lives_ok { $row = $ars->create({}) }
300 'empty insert works';
302 $row->discard_changes;
304 is $row->artistid, $current_artistid+1,
305 'empty insert generated correct PK';
307 # test that autoinc column still works after empty insert
308 $row = $ars->create({ name => 'after_empty_insert' });
310 is $row->artistid, $current_artistid+2,
311 'autoincrement column functional aftear empty insert';
313 # test blobs (stolen from 73oracle.t)
315 # turn off horrendous binary DBIC_TRACE output
317 local $schema->storage->{debug} = 0;
319 eval { local $^W = 0; $dbh->do('DROP TABLE bindtype_test') };
321 CREATE TABLE bindtype_test
323 id INT NOT NULL PRIMARY KEY,
329 ],{ RaiseError => 1, PrintError => 1 });
331 my $rs = $schema->resultset('BindType');
334 foreach my $type (qw( blob clob a_memo )) {
335 foreach my $size (qw( small large )) {
337 skip 'TEXT columns not cast to MEMO over ODBC', 2
338 if $type eq 'clob' && $size eq 'large' && $dsn =~ /:ODBC:/;
342 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
343 "inserted $size $type without dying" or next;
345 my $from_db = eval { $rs->find($id)->$type } || '';
348 ok($from_db eq $binstr{$size}, "verified inserted $size $type" )
351 join '', map sprintf('%02X', ord), split //, shift
353 diag 'Got: ', "\n", substr($hexdump->($from_db),0,255), '...',
354 substr($hexdump->($from_db),-255);
355 diag 'Size: ', length($from_db);
356 diag 'Expected Size: ', length($binstr{$size});
357 diag 'Expected: ', "\n",
358 substr($hexdump->($binstr{$size}), 0, 255),
359 "...", substr($hexdump->($binstr{$size}),-255);
366 $rs->search({ id => 0 })->update({ blob => $binstr{small} });
367 } 'updated IMAGE to small binstr without dying';
370 $rs->search({ id => 0 })->update({ blob => $binstr{large} });
371 } 'updated IMAGE to large binstr without dying';
374 # test GUIDs (and the cursor GUID fixup stuff for ADO)
377 $schema->storage->new_guid(sub { Data::GUID->new->as_string });
379 local $schema->source('ArtistGUID')->column_info('artistid')->{data_type}
382 local $schema->source('ArtistGUID')->column_info('a_guid')->{data_type}
385 $schema->storage->dbh_do (sub {
386 my ($storage, $dbh) = @_;
387 eval { local $^W = 0; $dbh->do("DROP TABLE artist_guid") };
389 CREATE TABLE artist_guid (
390 artistid GUID NOT NULL,
393 charfield CHAR(10) NULL,
395 primary key(artistid)
401 $row = $schema->resultset('ArtistGUID')->create({ name => 'mtfnpy' })
402 } 'created a row with a GUID';
405 eval { $row->artistid },
406 'row has GUID PK col populated',
411 eval { $row->a_guid },
412 'row has a GUID col with auto_nextval populated',
416 my $row_from_db = $schema->resultset('ArtistGUID')
417 ->search({ name => 'mtfnpy' })->first;
419 is $row_from_db->artistid, $row->artistid,
420 'PK GUID round trip (via ->search->next)';
422 is $row_from_db->a_guid, $row->a_guid,
423 'NON-PK GUID round trip (via ->search->next)';
425 $row_from_db = $schema->resultset('ArtistGUID')
426 ->find($row->artistid);
428 is $row_from_db->artistid, $row->artistid,
429 'PK GUID round trip (via ->find)';
431 is $row_from_db->a_guid, $row->a_guid,
432 'NON-PK GUID round trip (via ->find)';
434 ($row_from_db) = $schema->resultset('ArtistGUID')
435 ->search({ name => 'mtfnpy' })->all;
437 is $row_from_db->artistid, $row->artistid,
438 'PK GUID round trip (via ->search->all)';
440 is $row_from_db->a_guid, $row->a_guid,
441 'NON-PK GUID round trip (via ->search->all)';
449 if (my $storage = eval { $schema->storage }) {
450 # cannot drop a table if it has been used, have to reconnect first
451 $schema->storage->disconnect;
452 local $^W = 0; # for ADO OLE exceptions
453 $schema->storage->dbh->do("DROP TABLE $_")
454 for qw/artist track cd bindtype_test artist_guid/;