Refactor Statistics to clean up printing of debug info and to avoid crashing on
[dbsrgits/DBIx-Class.git] / lib / DBIx / Class / Manual / Cookbook.pod
CommitLineData
3b44ccc6 1=head1 NAME
9c82c181 2
40dbc108 3DBIx::Class::Manual::Cookbook - Miscellaneous recipes
ee38fa40 4
40dbc108 5=head1 RECIPES
2913b2d3 6
bade79c4 7=head2 Searching
faf62551 8
bade79c4 9=head3 Paged results
faf62551 10
bade79c4 11When you expect a large number of results, you can ask L<DBIx::Class> for a
12paged resultset, which will fetch only a small number of records at a time:
faf62551 13
bade79c4 14 my $rs = $schema->resultset('Artist')->search(
5e8b1b2a 15 undef,
bade79c4 16 {
17 page => 1, # page to return (defaults to 1)
18 rows => 10, # number of results per page
19 },
20 );
faf62551 21
bade79c4 22 return $rs->all(); # all records for page 1
faf62551 23
bade79c4 24The C<page> attribute does not have to be specified in your search:
25
26 my $rs = $schema->resultset('Artist')->search(
5e8b1b2a 27 undef,
bade79c4 28 {
29 rows => 10,
30 }
31 );
faf62551 32
bade79c4 33 return $rs->page(1); # DBIx::Class::ResultSet containing first 10 records
faf62551 34
35In either of the above cases, you can return a L<Data::Page> object for the
bade79c4 36resultset (suitable for use in e.g. a template) using the C<pager> method:
faf62551 37
bade79c4 38 return $rs->pager();
faf62551 39
bade79c4 40=head3 Complex WHERE clauses
2913b2d3 41
40dbc108 42Sometimes you need to formulate a query using specific operators:
43
ea6309e2 44 my @albums = $schema->resultset('Album')->search({
35d4fe78 45 artist => { 'like', '%Lamb%' },
46 title => { 'like', '%Fear of Fours%' },
47 });
40dbc108 48
49This results in something like the following C<WHERE> clause:
50
35d4fe78 51 WHERE artist LIKE '%Lamb%' AND title LIKE '%Fear of Fours%'
40dbc108 52
53Other queries might require slightly more complex logic:
54
ea6309e2 55 my @albums = $schema->resultset('Album')->search({
35d4fe78 56 -or => [
57 -and => [
58 artist => { 'like', '%Smashing Pumpkins%' },
59 title => 'Siamese Dream',
60 ],
61 artist => 'Starchildren',
62 ],
63 });
40dbc108 64
65This results in the following C<WHERE> clause:
66
35d4fe78 67 WHERE ( artist LIKE '%Smashing Pumpkins%' AND title = 'Siamese Dream' )
68 OR artist = 'Starchildren'
40dbc108 69
70For more information on generating complex queries, see
71L<SQL::Abstract/WHERE CLAUSES>.
ee38fa40 72
321d9634 73=head3 Arbitrary SQL through a custom ResultSource
74
75Sometimes you have to run arbitrary SQL because your query is too complex
76(e.g. it contains Unions, Sub-Selects, Stored Procedures, etc.) or has to
77be optimized for your database in a special way, but you still want to
78get the results as a L<DBIx::Class::ResultSet>.
79The recommended way to accomplish this is by defining a separate ResultSource
80for your query. You can then inject complete SQL statements using a scalar
81reference (this is a feature of L<SQL::Abstract>).
82
83Say you want to run a complex custom query on your user data, here's what
84you have to add to your User class:
85
86 package My::Schema::User;
87
88 use base qw/DBIx::Class/;
89
90 # ->load_components, ->table, ->add_columns, etc.
91
92 # Make a new ResultSource based on the User class
93 my $source = __PACKAGE__->result_source_instance();
94 my $new_source = $source->new( $source );
95 $new_source->source_name( 'UserFriendsComplex' );
96
97 # Hand in your query as a scalar reference
98 # It will be added as a sub-select after FROM,
99 # so pay attention to the surrounding brackets!
100 $new_source->name( \<<SQL );
101 ( SELECT u.* FROM user u
102 INNER JOIN user_friends f ON u.id = f.user_id
103 WHERE f.friend_user_id = ?
104 UNION
105 SELECT u.* FROM user u
106 INNER JOIN user_friends f ON u.id = f.friend_user_id
107 WHERE f.user_id = ? )
108 SQL
109
110 # Finally, register your new ResultSource with your Schema
111 My::Schema->register_source( 'UserFriendsComplex' => $new_source );
112
113Next, you can execute your complex query using bind parameters like this:
114
115 my $friends = [ $schema->resultset( 'UserFriendsComplex' )->search( {},
116 {
117 bind => [ 12345, 12345 ]
118 }
119 ) ];
120
121... and you'll get back a perfect L<DBIx::Class::ResultSet>.
122
bade79c4 123=head3 Using specific columns
faf62551 124
324572ca 125When you only want specific columns from a table, you can use
126C<columns> to specify which ones you need. This is useful to avoid
127loading columns with large amounts of data that you aren't about to
128use anyway:
faf62551 129
bade79c4 130 my $rs = $schema->resultset('Artist')->search(
5e8b1b2a 131 undef,
bade79c4 132 {
5e8b1b2a 133 columns => [qw/ name /]
bade79c4 134 }
135 );
faf62551 136
bade79c4 137 # Equivalent SQL:
138 # SELECT artist.name FROM artist
faf62551 139
324572ca 140This is a shortcut for C<select> and C<as>, see below. C<columns>
141cannot be used together with C<select> and C<as>.
142
bade79c4 143=head3 Using database functions or stored procedures
faf62551 144
bade79c4 145The combination of C<select> and C<as> can be used to return the result of a
146database function or stored procedure as a column value. You use C<select> to
147specify the source for your column value (e.g. a column name, function, or
148stored procedure name). You then use C<as> to set the column name you will use
149to access the returned value:
faf62551 150
bade79c4 151 my $rs = $schema->resultset('Artist')->search(
324572ca 152 {},
bade79c4 153 {
154 select => [ 'name', { LENGTH => 'name' } ],
155 as => [qw/ name name_length /],
156 }
157 );
faf62551 158
bade79c4 159 # Equivalent SQL:
98b65433 160 # SELECT name name, LENGTH( name )
bade79c4 161 # FROM artist
faf62551 162
d676881f 163Note that the C< as > attribute has absolutely nothing to with the sql
164syntax C< SELECT foo AS bar > (see the documentation in
165L<DBIx::Class::ResultSet/ATTRIBUTES>). If your alias exists as a
166column in your base class (i.e. it was added with C<add_columns>), you
167just access it as normal. Our C<Artist> class has a C<name> column, so
168we just use the C<name> accessor:
faf62551 169
bade79c4 170 my $artist = $rs->first();
171 my $name = $artist->name();
faf62551 172
173If on the other hand the alias does not correspond to an existing column, you
324572ca 174have to fetch the value using the C<get_column> accessor:
faf62551 175
bade79c4 176 my $name_length = $artist->get_column('name_length');
faf62551 177
bade79c4 178If you don't like using C<get_column>, you can always create an accessor for
faf62551 179any of your aliases using either of these:
180
bade79c4 181 # Define accessor manually:
182 sub name_length { shift->get_column('name_length'); }
faf62551 183
bade79c4 184 # Or use DBIx::Class::AccessorGroup:
185 __PACKAGE__->mk_group_accessors('column' => 'name_length');
faf62551 186
bade79c4 187=head3 SELECT DISTINCT with multiple columns
faf62551 188
bade79c4 189 my $rs = $schema->resultset('Foo')->search(
324572ca 190 {},
bade79c4 191 {
192 select => [
193 { distinct => [ $source->columns ] }
194 ],
d676881f 195 as => [ $source->columns ] # remember 'as' is not the same as SQL AS :-)
bade79c4 196 }
197 );
faf62551 198
286f32b3 199 my $count = $rs->next->get_column('count');
200
bade79c4 201=head3 SELECT COUNT(DISTINCT colname)
6607ee1b 202
bade79c4 203 my $rs = $schema->resultset('Foo')->search(
324572ca 204 {},
bade79c4 205 {
206 select => [
207 { count => { distinct => 'colname' } }
208 ],
209 as => [ 'count' ]
210 }
211 );
6607ee1b 212
bade79c4 213=head3 Grouping results
214
215L<DBIx::Class> supports C<GROUP BY> as follows:
216
217 my $rs = $schema->resultset('Artist')->search(
324572ca 218 {},
bade79c4 219 {
220 join => [qw/ cds /],
221 select => [ 'name', { count => 'cds.cdid' } ],
222 as => [qw/ name cd_count /],
223 group_by => [qw/ name /]
224 }
225 );
6607ee1b 226
bade79c4 227 # Equivalent SQL:
228 # SELECT name, COUNT( cds.cdid ) FROM artist me
229 # LEFT JOIN cd cds ON ( cds.artist = me.artistid )
230 # GROUP BY name
6607ee1b 231
d676881f 232Please see L<DBIx::Class::ResultSet/ATTRIBUTES> documentation if you
233are in any way unsure about the use of the attributes above (C< join
234>, C< select >, C< as > and C< group_by >).
235
74dc2edc 236=head3 Predefined searches
237
324572ca 238You can write your own L<DBIx::Class::ResultSet> class by inheriting from it
74dc2edc 239and define often used searches as methods:
240
241 package My::DBIC::ResultSet::CD;
242 use strict;
243 use warnings;
244 use base 'DBIx::Class::ResultSet';
245
246 sub search_cds_ordered {
247 my ($self) = @_;
248
249 return $self->search(
250 {},
251 { order_by => 'name DESC' },
252 );
253 }
254
255 1;
256
257To use your resultset, first tell DBIx::Class to create an instance of it
258for you, in your My::DBIC::Schema::CD class:
259
260 __PACKAGE__->resultset_class('My::DBIC::ResultSet::CD');
261
262Then call your new method in your code:
263
264 my $ordered_cds = $schema->resultset('CD')->search_cds_ordered();
265
87980de7 266=head2 Using joins and prefetch
267
bade79c4 268You can use the C<join> attribute to allow searching on, or sorting your
269results by, one or more columns in a related table. To return all CDs matching
270a particular artist name:
ea6309e2 271
bade79c4 272 my $rs = $schema->resultset('CD')->search(
273 {
274 'artist.name' => 'Bob Marley'
275 },
276 {
277 join => [qw/artist/], # join the artist table
278 }
279 );
280
281 # Equivalent SQL:
282 # SELECT cd.* FROM cd
283 # JOIN artist ON cd.artist = artist.id
284 # WHERE artist.name = 'Bob Marley'
285
286If required, you can now sort on any column in the related tables by including
287it in your C<order_by> attribute:
288
289 my $rs = $schema->resultset('CD')->search(
290 {
291 'artist.name' => 'Bob Marley'
292 },
293 {
294 join => [qw/ artist /],
295 order_by => [qw/ artist.name /]
296 }
2f81ed0f 297 );
ea6309e2 298
bade79c4 299 # Equivalent SQL:
300 # SELECT cd.* FROM cd
301 # JOIN artist ON cd.artist = artist.id
302 # WHERE artist.name = 'Bob Marley'
303 # ORDER BY artist.name
ea6309e2 304
bade79c4 305Note that the C<join> attribute should only be used when you need to search or
306sort using columns in a related table. Joining related tables when you only
307need columns from the main table will make performance worse!
ea6309e2 308
bade79c4 309Now let's say you want to display a list of CDs, each with the name of the
310artist. The following will work fine:
ea6309e2 311
bade79c4 312 while (my $cd = $rs->next) {
313 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
314 }
ea6309e2 315
bade79c4 316There is a problem however. We have searched both the C<cd> and C<artist> tables
317in our main query, but we have only returned data from the C<cd> table. To get
318the artist name for any of the CD objects returned, L<DBIx::Class> will go back
319to the database:
ea6309e2 320
bade79c4 321 SELECT artist.* FROM artist WHERE artist.id = ?
ea6309e2 322
323A statement like the one above will run for each and every CD returned by our
324main query. Five CDs, five extra queries. A hundred CDs, one hundred extra
325queries!
326
bade79c4 327Thankfully, L<DBIx::Class> has a C<prefetch> attribute to solve this problem.
897342e4 328This allows you to fetch results from related tables in advance:
ea6309e2 329
bade79c4 330 my $rs = $schema->resultset('CD')->search(
331 {
332 'artist.name' => 'Bob Marley'
333 },
334 {
335 join => [qw/ artist /],
336 order_by => [qw/ artist.name /],
337 prefetch => [qw/ artist /] # return artist data too!
338 }
339 );
ea6309e2 340
bade79c4 341 # Equivalent SQL (note SELECT from both "cd" and "artist"):
342 # SELECT cd.*, artist.* FROM cd
343 # JOIN artist ON cd.artist = artist.id
344 # WHERE artist.name = 'Bob Marley'
345 # ORDER BY artist.name
ea6309e2 346
347The code to print the CD list remains the same:
348
bade79c4 349 while (my $cd = $rs->next) {
350 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
351 }
ea6309e2 352
bade79c4 353L<DBIx::Class> has now prefetched all matching data from the C<artist> table,
ea6309e2 354so no additional SQL statements are executed. You now have a much more
355efficient query.
356
77d6b403 357Note that as of L<DBIx::Class> 0.05999_01, C<prefetch> I<can> be used with
358C<has_many> relationships.
ea6309e2 359
bade79c4 360Also note that C<prefetch> should only be used when you know you will
ea6309e2 361definitely use data from a related table. Pre-fetching related tables when you
362only need columns from the main table will make performance worse!
363
bade79c4 364=head3 Multi-step joins
ea6309e2 365
366Sometimes you want to join more than one relationship deep. In this example,
bade79c4 367we want to find all C<Artist> objects who have C<CD>s whose C<LinerNotes>
368contain a specific string:
369
370 # Relationships defined elsewhere:
371 # Artist->has_many('cds' => 'CD', 'artist');
372 # CD->has_one('liner_notes' => 'LinerNotes', 'cd');
373
374 my $rs = $schema->resultset('Artist')->search(
375 {
376 'liner_notes.notes' => { 'like', '%some text%' },
377 },
378 {
379 join => {
380 'cds' => 'liner_notes'
381 }
382 }
383 );
ea6309e2 384
bade79c4 385 # Equivalent SQL:
386 # SELECT artist.* FROM artist
387 # JOIN ( cd ON artist.id = cd.artist )
388 # JOIN ( liner_notes ON cd.id = liner_notes.cd )
389 # WHERE liner_notes.notes LIKE '%some text%'
ea6309e2 390
391Joins can be nested to an arbitrary level. So if we decide later that we
392want to reduce the number of Artists returned based on who wrote the liner
393notes:
394
bade79c4 395 # Relationship defined elsewhere:
396 # LinerNotes->belongs_to('author' => 'Person');
397
398 my $rs = $schema->resultset('Artist')->search(
399 {
400 'liner_notes.notes' => { 'like', '%some text%' },
401 'author.name' => 'A. Writer'
402 },
403 {
404 join => {
405 'cds' => {
406 'liner_notes' => 'author'
ea6309e2 407 }
bade79c4 408 }
409 }
410 );
ea6309e2 411
bade79c4 412 # Equivalent SQL:
413 # SELECT artist.* FROM artist
414 # JOIN ( cd ON artist.id = cd.artist )
415 # JOIN ( liner_notes ON cd.id = liner_notes.cd )
416 # JOIN ( author ON author.id = liner_notes.author )
417 # WHERE liner_notes.notes LIKE '%some text%'
418 # AND author.name = 'A. Writer'
87980de7 419
897342e4 420=head2 Multi-step prefetch
421
422From 0.04999_05 onwards, C<prefetch> can be nested more than one relationship
423deep using the same syntax as a multi-step join:
424
425 my $rs = $schema->resultset('Tag')->search(
ac2803ef 426 {},
897342e4 427 {
428 prefetch => {
429 cd => 'artist'
430 }
431 }
432 );
433
434 # Equivalent SQL:
435 # SELECT tag.*, cd.*, artist.* FROM tag
436 # JOIN cd ON tag.cd = cd.cdid
437 # JOIN artist ON cd.artist = artist.artistid
438
439Now accessing our C<cd> and C<artist> relationships does not need additional
440SQL statements:
441
442 my $tag = $rs->first;
443 print $tag->cd->artist->name;
444
ac2803ef 445=head2 Columns of data
446
447If you want to find the sum of a particular column there are several
448ways, the obvious one is to use search:
449
450 my $rs = $schema->resultset('Items')->search(
451 {},
452 {
453 select => [ { sum => 'Cost' } ],
d676881f 454 as => [ 'total_cost' ], # remember this 'as' is for DBIx::Class::ResultSet not SQL
ac2803ef 455 }
456 );
457 my $tc = $rs->first->get_column('total_cost');
458
459Or, you can use the L<DBIx::Class::ResultSetColumn>, which gets
460returned when you ask the C<ResultSet> for a column using
461C<get_column>:
462
463 my $cost = $schema->resultset('Items')->get_column('Cost');
464 my $tc = $cost->sum;
465
466With this you can also do:
467
468 my $minvalue = $cost->min;
469 my $maxvalue = $cost->max;
470
471Or just iterate through the values of this column only:
472
473 while ( my $c = $cost->next ) {
474 print $c;
475 }
476
477 foreach my $c ($cost->all) {
478 print $c;
479 }
480
709353af 481C<ResultSetColumn> only has a limited number of built-in functions, if
482you need one that it doesn't have, then you can use the C<func> method
483instead:
484
485 my $avg = $cost->func('AVERAGE');
486
487This will cause the following SQL statement to be run:
488
489 SELECT AVERAGE(Cost) FROM Items me
490
491Which will of course only work if your database supports this function.
ac2803ef 492See L<DBIx::Class::ResultSetColumn> for more documentation.
493
acee4e4d 494=head2 Using relationships
495
496=head3 Create a new row in a related table
497
498 my $book->create_related('author', { name => 'Fred'});
499
500=head3 Search in a related table
501
502Only searches for books named 'Titanic' by the author in $author.
503
504 my $author->search_related('books', { name => 'Titanic' });
505
506=head3 Delete data in a related table
507
508Deletes only the book named Titanic by the author in $author.
509
510 my $author->delete_related('books', { name => 'Titanic' });
511
f8bad769 512=head3 Ordering a relationship result set
513
514If you always want a relation to be ordered, you can specify this when you
515create the relationship.
516
517To order C<< $book->pages >> by descending page_number.
518
519 Book->has_many('pages' => 'Page', 'book', { order_by => \'page_number DESC'} );
520
521
522
87980de7 523=head2 Transactions
524
525As of version 0.04001, there is improved transaction support in
85f78622 526L<DBIx::Class::Storage> and L<DBIx::Class::Schema>. Here is an
181a28f4 527example of the recommended way to use it:
87980de7 528
181a28f4 529 my $genus = $schema->resultset('Genus')->find(12);
530
70634260 531 my $coderef2 = sub {
532 $genus->extinct(1);
533 $genus->update;
534 };
535
181a28f4 536 my $coderef1 = sub {
35d4fe78 537 $genus->add_to_species({ name => 'troglodyte' });
538 $genus->wings(2);
539 $genus->update;
70634260 540 $schema->txn_do($coderef2); # Can have a nested transaction
181a28f4 541 return $genus->species;
542 };
543
181a28f4 544 my $rs;
545 eval {
70634260 546 $rs = $schema->txn_do($coderef1);
181a28f4 547 };
548
549 if ($@) { # Transaction failed
550 die "the sky is falling!" #
551 if ($@ =~ /Rollback failed/); # Rollback failed
552
553 deal_with_failed_transaction();
35d4fe78 554 }
87980de7 555
181a28f4 556Nested transactions will work as expected. That is, only the outermost
557transaction will actually issue a commit to the $dbh, and a rollback
558at any level of any transaction will cause the entire nested
559transaction to fail. Support for savepoints and for true nested
40dbc108 560transactions (for databases that support them) will hopefully be added
561in the future.
ee38fa40 562
130c6439 563=head2 Many-to-many relationships
ee38fa40 564
787d6a29 565This is straightforward using L<ManyToMany|DBIx::Class::Relationship/many_to_many>:
ea6309e2 566
bade79c4 567 package My::DB;
568 # ... set up connection ...
569
570 package My::User;
571 use base 'My::DB';
572 __PACKAGE__->table('user');
573 __PACKAGE__->add_columns(qw/id name/);
574 __PACKAGE__->set_primary_key('id');
575 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'user');
576 __PACKAGE__->many_to_many('addresses' => 'user_address', 'address');
577
578 package My::UserAddress;
579 use base 'My::DB';
580 __PACKAGE__->table('user_address');
581 __PACKAGE__->add_columns(qw/user address/);
582 __PACKAGE__->set_primary_key(qw/user address/);
583 __PACKAGE__->belongs_to('user' => 'My::User');
584 __PACKAGE__->belongs_to('address' => 'My::Address');
585
586 package My::Address;
587 use base 'My::DB';
588 __PACKAGE__->table('address');
589 __PACKAGE__->add_columns(qw/id street town area_code country/);
590 __PACKAGE__->set_primary_key('id');
591 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'address');
592 __PACKAGE__->many_to_many('users' => 'user_address', 'user');
593
594 $rs = $user->addresses(); # get all addresses for a user
595 $rs = $address->users(); # get all users for an address
596
597=head2 Setting default values for a row
a00e1684 598
35d4fe78 599It's as simple as overriding the C<new> method. Note the use of
40dbc108 600C<next::method>.
a00e1684 601
35d4fe78 602 sub new {
603 my ( $class, $attrs ) = @_;
40dbc108 604
35d4fe78 605 $attrs->{foo} = 'bar' unless defined $attrs->{foo};
40dbc108 606
df65edd2 607 my $new = $class->next::method($attrs);
8b50216e 608
df65edd2 609 return $new;
35d4fe78 610 }
a00e1684 611
4a3c6354 612For more information about C<next::method>, look in the L<Class::C3>
613documentation. See also L<DBIx::Class::Manual::Component> for more
614ways to write your own base classes to do this.
615
616People looking for ways to do "triggers" with DBIx::Class are probably
ab872312 617just looking for this.
4a3c6354 618
25af00d7 619=head2 Stringification
620
40dbc108 621Employ the standard stringification technique by using the C<overload>
462bb847 622module.
623
624To make an object stringify itself as a single column, use something
625like this (replace C<foo> with the column/method of your choice):
25af00d7 626
0472cc04 627 use overload '""' => sub { shift->name}, fallback => 1;
25af00d7 628
462bb847 629For more complex stringification, you can use an anonymous subroutine:
630
631 use overload '""' => sub { $_[0]->name . ", " .
632 $_[0]->address }, fallback => 1;
633
324572ca 634=head3 Stringification Example
462bb847 635
636Suppose we have two tables: C<Product> and C<Category>. The table
637specifications are:
638
639 Product(id, Description, category)
640 Category(id, Description)
641
642C<category> is a foreign key into the Category table.
643
644If you have a Product object C<$obj> and write something like
645
646 print $obj->category
647
648things will not work as expected.
649
650To obtain, for example, the category description, you should add this
651method to the class defining the Category table:
652
653 use overload "" => sub {
654 my $self = shift;
655
656 return $self->Description;
77713550 657 }, fallback => 1;
462bb847 658
bade79c4 659=head2 Disconnecting cleanly
660
661If you find yourself quitting an app with Control-C a lot during
662development, you might like to put the following signal handler in
663your main database class to make sure it disconnects cleanly:
664
665 $SIG{INT} = sub {
6d1bf0a9 666 __PACKAGE__->storage->disconnect;
bade79c4 667 };
668
362500af 669=head2 Schema import/export
670
671This functionality requires you to have L<SQL::Translator> (also known as
672"SQL Fairy") installed.
673
674To create a DBIx::Class schema from an existing database:
675
676 sqlt --from DBI
677 --to DBIx::Class::File
678 --prefix "MySchema" > MySchema.pm
679
680To create a MySQL database from an existing L<DBIx::Class> schema, convert the
681schema to MySQL's dialect of SQL:
682
54c30987 683 sqlt --from SQL::Translator::Parser::DBIx::Class
684 --to MySQL
685 --DBIx::Class "MySchema.pm" > Schema1.sql
362500af 686
687And import using the mysql client:
688
689 mysql -h "host" -D "database" -u "user" -p < Schema1.sql
690
b0a20454 691=head2 Easy migration from class-based to schema-based setup
692
693You want to start using the schema-based approach to L<DBIx::Class>
694(see L<SchemaIntro.pod>), but have an established class-based setup with lots
695of existing classes that you don't want to move by hand. Try this nifty script
696instead:
697
698 use MyDB;
699 use SQL::Translator;
700
701 my $schema = MyDB->schema_instance;
702
703 my $translator = SQL::Translator->new(
704 debug => $debug || 0,
705 trace => $trace || 0,
706 no_comments => $no_comments || 0,
707 show_warnings => $show_warnings || 0,
708 add_drop_table => $add_drop_table || 0,
709 validate => $validate || 0,
710 parser_args => {
711 'DBIx::Schema' => $schema,
c5f36986 712 },
b0a20454 713 producer_args => {
714 'prefix' => 'My::Schema',
c5f36986 715 },
b0a20454 716 );
717
d240abac 718 $translator->parser('SQL::Translator::Parser::DBIx::Class');
719 $translator->producer('SQL::Translator::Producer::DBIx::Class::File');
b0a20454 720
721 my $output = $translator->translate(@args) or die
722 "Error: " . $translator->error;
723
724 print $output;
725
726You could use L<Module::Find> to search for all subclasses in the MyDB::*
880a1a0c 727namespace, which is currently left as an exercise for the reader.
b0a20454 728
362500af 729=head2 Schema versioning
730
731The following example shows simplistically how you might use DBIx::Class to
732deploy versioned schemas to your customers. The basic process is as follows:
733
da4779ad 734=over 4
735
736=item 1.
737
738Create a DBIx::Class schema
739
740=item 2.
741
742Save the schema
743
744=item 3.
745
746Deploy to customers
747
748=item 4.
749
750Modify schema to change functionality
751
752=item 5.
753
754Deploy update to customers
755
756=back
362500af 757
758=head3 Create a DBIx::Class schema
759
760This can either be done manually, or generated from an existing database as
761described under C<Schema import/export>.
762
763=head3 Save the schema
764
765Use C<sqlt> to transform your schema into an SQL script suitable for your
766customer's database. E.g. for MySQL:
767
54c30987 768 sqlt --from SQL::Translator::Parser::DBIx::Class
362500af 769 --to MySQL
770 --DBIx::Class "MySchema.pm" > Schema1.mysql.sql
771
772If you need to target databases from multiple vendors, just generate an SQL
773script suitable for each. To support PostgreSQL too:
774
54c30987 775 sqlt --from SQL::Translator::DBIx::Class
362500af 776 --to PostgreSQL
777 --DBIx::Class "MySchema.pm" > Schema1.pgsql.sql
778
779=head3 Deploy to customers
780
781There are several ways you could deploy your schema. These are probably
782beyond the scope of this recipe, but might include:
783
da4779ad 784=over 4
785
786=item 1.
787
788Require customer to apply manually using their RDBMS.
789
790=item 2.
791
792Package along with your app, making database dump/schema update/tests
362500af 793all part of your install.
794
da4779ad 795=back
796
362500af 797=head3 Modify the schema to change functionality
798
799As your application evolves, it may be necessary to modify your schema to
800change functionality. Once the changes are made to your schema in DBIx::Class,
801export the modified schema as before, taking care not to overwrite the original:
802
54c30987 803 sqlt --from SQL::Translator::DBIx::Class
362500af 804 --to MySQL
805 --DBIx::Class "Anything.pm" > Schema2.mysql.sql
806
807Next, use sqlt-diff to create an SQL script that will update the customer's
808database schema:
809
810 sqlt-diff --to MySQL Schema1=MySQL Schema2=MySQL > SchemaUpdate.mysql.sql
811
812=head3 Deploy update to customers
813
814The schema update can be deployed to customers using the same method as before.
815
7be93b07 816=head2 Setting limit dialect for SQL::Abstract::Limit
817
324572ca 818In some cases, SQL::Abstract::Limit cannot determine the dialect of
819the remote SQL server by looking at the database handle. This is a
820common problem when using the DBD::JDBC, since the DBD-driver only
821know that in has a Java-driver available, not which JDBC driver the
822Java component has loaded. This specifically sets the limit_dialect
823to Microsoft SQL-server (See more names in SQL::Abstract::Limit
824-documentation.
7be93b07 825
826 __PACKAGE__->storage->sql_maker->limit_dialect('mssql');
827
324572ca 828The JDBC bridge is one way of getting access to a MSSQL server from a platform
7be93b07 829that Microsoft doesn't deliver native client libraries for. (e.g. Linux)
830
324572ca 831=head2 Setting quoting for the generated SQL.
2437a1e3 832
324572ca 833If the database contains column names with spaces and/or reserved words, they
834need to be quoted in the SQL queries. This is done using:
2437a1e3 835
836 __PACKAGE__->storage->sql_maker->quote_char([ qw/[ ]/] );
837 __PACKAGE__->storage->sql_maker->name_sep('.');
838
324572ca 839The first sets the quote characters. Either a pair of matching
840brackets, or a C<"> or C<'>:
2437a1e3 841
842 __PACKAGE__->storage->sql_maker->quote_char('"');
843
324572ca 844Check the documentation of your database for the correct quote
845characters to use. C<name_sep> needs to be set to allow the SQL
846generator to put the quotes the correct place.
2437a1e3 847
086b93a2 848=head2 Overloading methods
849
ab872312 850L<DBIx::Class> uses the L<Class::C3> package, which provides for redispatch of
851method calls, useful for things like default values and triggers. You have to
852use calls to C<next::method> to overload methods. More information on using
853L<Class::C3> with L<DBIx::Class> can be found in
086b93a2 854L<DBIx::Class::Manual::Component>.
855
856=head3 Changing one field whenever another changes
857
858For example, say that you have three columns, C<id>, C<number>, and
859C<squared>. You would like to make changes to C<number> and have
860C<squared> be automagically set to the value of C<number> squared.
861You can accomplish this by overriding C<store_column>:
862
863 sub store_column {
864 my ( $self, $name, $value ) = @_;
865 if ($name eq 'number') {
866 $self->squared($value * $value);
867 }
868 $self->next::method($name, $value);
869 }
870
871Note that the hard work is done by the call to C<next::method>, which
324572ca 872redispatches your call to store_column in the superclass(es).
086b93a2 873
874=head3 Automatically creating related objects
875
324572ca 876You might have a class C<Artist> which has many C<CD>s. Further, if you
086b93a2 877want to create a C<CD> object every time you insert an C<Artist> object.
ccbebdbc 878You can accomplish this by overriding C<insert> on your objects:
086b93a2 879
880 sub insert {
ccbebdbc 881 my ( $self, @args ) = @_;
882 $self->next::method(@args);
086b93a2 883 $self->cds->new({})->fill_from_artist($self)->insert;
884 return $self;
885 }
886
887where C<fill_from_artist> is a method you specify in C<CD> which sets
888values in C<CD> based on the data in the C<Artist> object you pass in.
889
1def3451 890=head2 Debugging DBIx::Class objects with Data::Dumper
891
892L<Data::Dumper> can be a very useful tool for debugging, but sometimes it can
893be hard to find the pertinent data in all the data it can generate.
894Specifically, if one naively tries to use it like so,
895
896 use Data::Dumper;
897
898 my $cd = $schema->resultset('CD')->find(1);
899 print Dumper($cd);
900
901several pages worth of data from the CD object's schema and result source will
902be dumped to the screen. Since usually one is only interested in a few column
903values of the object, this is not very helpful.
904
905Luckily, it is possible to modify the data before L<Data::Dumper> outputs
906it. Simply define a hook that L<Data::Dumper> will call on the object before
907dumping it. For example,
908
909 package My::DB::CD;
910
911 sub _dumper_hook {
99fb1058 912 $_[0] = bless {
913 %{ $_[0] },
1def3451 914 result_source => undef,
99fb1058 915 }, ref($_[0]);
1def3451 916 }
917
918 [...]
919
920 use Data::Dumper;
921
22139027 922 local $Data::Dumper::Freezer = '_dumper_hook';
1def3451 923
924 my $cd = $schema->resultset('CD')->find(1);
925 print Dumper($cd);
926 # dumps $cd without its ResultSource
927
928If the structure of your schema is such that there is a common base class for
929all your table classes, simply put a method similar to C<_dumper_hook> in the
930base class and set C<$Data::Dumper::Freezer> to its name and L<Data::Dumper>
931will automagically clean up your data before printing it. See
932L<Data::Dumper/EXAMPLES> for more information.
933
1def3451 934=head2 Retrieving a row object's Schema
935
324572ca 936It is possible to get a Schema object from a row object like so:
1def3451 937
938 my $schema = $cd->result_source->schema;
324572ca 939 # use the schema as normal:
940 my $artist_rs = $schema->resultset('Artist');
1def3451 941
942This can be useful when you don't want to pass around a Schema object to every
943method.
944
4c248161 945=head2 Profiling
946
85f78622 947When you enable L<DBIx::Class::Storage>'s debugging it prints the SQL
4c248161 948executed as well as notifications of query completion and transaction
949begin/commit. If you'd like to profile the SQL you can subclass the
950L<DBIx::Class::Storage::Statistics> class and write your own profiling
951mechanism:
952
953 package My::Profiler;
954 use strict;
955
956 use base 'DBIx::Class::Storage::Statistics';
957
958 use Time::HiRes qw(time);
959
960 my $start;
961
962 sub query_start {
963 my $self = shift();
964 my $sql = shift();
965 my $params = @_;
966
70f39278 967 $self->print("Executing $sql: ".join(', ', @params)."\n");
4c248161 968 $start = time();
969 }
970
971 sub query_end {
972 my $self = shift();
973 my $sql = shift();
974 my @params = @_;
975
70f39278 976 my $elapsed = sprintf("%0.4f", time() - $start);
977 $self->print("Execution took $elapsed seconds.\n");
4c248161 978 $start = undef;
979 }
980
981 1;
982
983You can then install that class as the debugging object:
984
70f39278 985 __PACKAGE__->storage->debugobj(new My::Profiler());
986 __PACKAGE__->storage->debug(1);
4c248161 987
988A more complicated example might involve storing each execution of SQL in an
989array:
990
991 sub query_end {
992 my $self = shift();
993 my $sql = shift();
994 my @params = @_;
995
996 my $elapsed = time() - $start;
997 push(@{ $calls{$sql} }, {
998 params => \@params,
999 elapsed => $elapsed
1000 });
1001 }
1002
1003You could then create average, high and low execution times for an SQL
1004statement and dig down to see if certain parameters cause aberrant behavior.
70f39278 1005You might want to check out L<DBIx::Class::QueryLog> as well.
4c248161 1006
e8e9e5c7 1007=head2 Getting the value of the primary key for the last database insert
1008
74413b83 1009AKA getting last_insert_id
1010
e8e9e5c7 1011If you are using PK::Auto, this is straightforward:
1012
74413b83 1013 my $foo = $rs->create(\%blah);
e8e9e5c7 1014 # do more stuff
1015 my $id = $foo->id; # foo->my_primary_key_field will also work.
1016
1017If you are not using autoincrementing primary keys, this will probably
1018not work, but then you already know the value of the last primary key anyway.
1019
824f4422 1020=head2 Dynamic Sub-classing DBIx::Class proxy classes
1021(AKA multi-class object inflation from one table)
1022
324572ca 1023L<DBIx::Class> classes are proxy classes, therefore some different
1024techniques need to be employed for more than basic subclassing. In
1025this example we have a single user table that carries a boolean bit
1026for admin. We would like like to give the admin users
1027objects(L<DBIx::Class::Row>) the same methods as a regular user but
1028also special admin only methods. It doesn't make sense to create two
1029seperate proxy-class files for this. We would be copying all the user
1030methods into the Admin class. There is a cleaner way to accomplish
1031this.
1032
c6d147b6 1033Overriding the C<inflate_result> method within the User proxy-class
324572ca 1034gives us the effect we want. This method is called by
1035L<DBIx::Class::ResultSet> when inflating a result from storage. So we
1036grab the object being returned, inspect the values we are looking for,
1037bless it if it's an admin object, and then return it. See the example
1038below:
824f4422 1039
1040B<Schema Definition>
1041
1042 package DB::Schema;
1043
1044 use base qw/DBIx::Class::Schema/;
1045
1046 __PACKAGE__->load_classes(qw/User/);
1047
1048
1049B<Proxy-Class definitions>
1050
1051 package DB::Schema::User;
1052
1053 use strict;
1054 use warnings;
1055 use base qw/DBIx::Class/;
1056
1057 ### Defined what our admin class is for ensure_class_loaded
1058 my $admin_class = __PACKAGE__ . '::Admin';
1059
324572ca 1060 __PACKAGE__->load_components(qw/Core/);
824f4422 1061
1062 __PACKAGE__->table('users');
1063
1064 __PACKAGE__->add_columns(qw/user_id email password
1065 firstname lastname active
1066 admin/);
1067
1068 __PACKAGE__->set_primary_key('user_id');
1069
1070 sub inflate_result {
1071 my $self = shift;
1072 my $ret = $self->next::method(@_);
1073 if( $ret->admin ) {### If this is an admin rebless for extra functions
1074 $self->ensure_class_loaded( $admin_class );
1075 bless $ret, $admin_class;
1076 }
1077 return $ret;
1078 }
1079
1080 sub hello {
1081 print "I am a regular user.\n";
1082 return ;
1083 }
1084
1085
1086 package DB::Schema::User::Admin;
1087
1088 use strict;
1089 use warnings;
1090 use base qw/DB::Schema::User/;
1091
1092 sub hello
1093 {
1094 print "I am an admin.\n";
1095 return;
1096 }
1097
1098 sub do_admin_stuff
1099 {
1100 print "I am doing admin stuff\n";
1101 return ;
1102 }
1103
1104B<Test File> test.pl
1105
1106 use warnings;
1107 use strict;
1108 use DB::Schema;
1109
1110 my $user_data = { email => 'someguy@place.com',
1111 password => 'pass1',
1112 admin => 0 };
1113
1114 my $admin_data = { email => 'someadmin@adminplace.com',
1115 password => 'pass2',
1116 admin => 1 };
1117
1118 my $schema = DB::Schema->connection('dbi:Pg:dbname=test');
1119
1120 $schema->resultset('User')->create( $user_data );
1121 $schema->resultset('User')->create( $admin_data );
1122
1123 ### Now we search for them
1124 my $user = $schema->resultset('User')->single( $user_data );
1125 my $admin = $schema->resultset('User')->single( $admin_data );
1126
1127 print ref $user, "\n";
1128 print ref $admin, "\n";
1129
1130 print $user->password , "\n"; # pass1
1131 print $admin->password , "\n";# pass2; inherited from User
1132 print $user->hello , "\n";# I am a regular user.
1133 print $admin->hello, "\n";# I am an admin.
1134
1135 ### The statement below will NOT print
1136 print "I can do admin stuff\n" if $user->can('do_admin_stuff');
1137 ### The statement below will print
1138 print "I can do admin stuff\n" if $admin->can('do_admin_stuff');
1139
fe5cf259 1140=head2 Skip object creation for faster results
1141
1142DBIx::Class is not built for speed, it's built for convenience and
1143ease of use, but sometimes you just need to get the data, and skip the
137c657c 1144fancy objects.
1145
1146To do this simply use L<DBIx::Class::ResultClass::HashRefInflator>.
1147
1148 my $rs = $schema->resultset('CD');
1149
1150 $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
1151
1152 my $hash_ref = $rs->find(1);
1153
1154Wasn't that easy?
1155
685dad64 1156=head2 Get raw data for blindingly fast results
1157
1158If the C<inflate_result> solution above is not fast enough for you, you
1159can use a DBIx::Class to return values exactly as they come out of the
1160data base with none of the convenience methods wrapped round them.
1161
1162This is used like so:-
1163
1164 my $cursor = $rs->cursor
1165 while (my @vals = $cursor->next) {
1166 # use $val[0..n] here
1167 }
1168
1169You will need to map the array offsets to particular columns (you can
1170use the I<select> attribute of C<search()> to force ordering).
1171
9e4c2514 1172=head2 Want to know if find_or_create found or created a row?
1173
1174Just use C<find_or_new> instead, then check C<in_storage>:
fe5cf259 1175
9e4c2514 1176 my $obj = $rs->find_or_new({ blah => 'blarg' });
1177 unless ($obj->in_storage) {
1178 $obj->insert;
1179 # do whatever else you wanted if it was a new row
1180 }
1181
7aaec96c 1182=head3 Wrapping/overloading a column accessor
1183
1184Problem: Say you have a table "Camera" and want to associate a description
1185with each camera. For most cameras, you'll be able to generate the description from
1186the other columns. However, in a few special cases you may want to associate a
1187custom description with a camera.
1188
1189Solution:
1190
1191In your database schema, define a description field in the "Camera" table that
1192can contain text and null values.
1193
1194In DBIC, we'll overload the column accessor to provide a sane default if no
1195custom description is defined. The accessor will either return or generate the
1196description, depending on whether the field is null or not.
1197
1198First, in your "Camera" schema class, define the description field as follows:
1199
1200 __PACKAGE__->add_columns(description => { accessor => '_description' });
1201
1202Next, we'll define the accessor-wrapper subroutine:
1203
1204 sub description {
1205 my $self = shift;
1206
1207 # If there is an update to the column, we'll let the original accessor
1208 # deal with it.
1209 return $self->_description(@_) if @_;
1210
1211 # Fetch the column value.
1212 my $description = $self->_description;
1213
1214 # If there's something in the description field, then just return that.
1215 return $description if defined $description && length $descripton;
1216
1217 # Otherwise, generate a description.
1218 return $self->generate_description;
1219 }
1220
40dbc108 1221=cut