Doc patch from jhannah
[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
d2f3e87b 5=head1 SEARCHING
2913b2d3 6
d2f3e87b 7=head2 Paged results
faf62551 8
bade79c4 9When you expect a large number of results, you can ask L<DBIx::Class> for a
264f1571 10paged resultset, which will fetch only a defined number of records at a time:
faf62551 11
bade79c4 12 my $rs = $schema->resultset('Artist')->search(
5e8b1b2a 13 undef,
bade79c4 14 {
15 page => 1, # page to return (defaults to 1)
16 rows => 10, # number of results per page
17 },
18 );
faf62551 19
bade79c4 20 return $rs->all(); # all records for page 1
faf62551 21
bade79c4 22The C<page> attribute does not have to be specified in your search:
23
24 my $rs = $schema->resultset('Artist')->search(
5e8b1b2a 25 undef,
bade79c4 26 {
27 rows => 10,
28 }
29 );
faf62551 30
bade79c4 31 return $rs->page(1); # DBIx::Class::ResultSet containing first 10 records
faf62551 32
264f1571 33In either of the above cases, you can get a L<Data::Page> object for the
bade79c4 34resultset (suitable for use in e.g. a template) using the C<pager> method:
faf62551 35
bade79c4 36 return $rs->pager();
faf62551 37
d2f3e87b 38=head2 Complex WHERE clauses
2913b2d3 39
40dbc108 40Sometimes you need to formulate a query using specific operators:
41
ea6309e2 42 my @albums = $schema->resultset('Album')->search({
35d4fe78 43 artist => { 'like', '%Lamb%' },
44 title => { 'like', '%Fear of Fours%' },
45 });
40dbc108 46
47This results in something like the following C<WHERE> clause:
48
35d4fe78 49 WHERE artist LIKE '%Lamb%' AND title LIKE '%Fear of Fours%'
40dbc108 50
51Other queries might require slightly more complex logic:
52
ea6309e2 53 my @albums = $schema->resultset('Album')->search({
35d4fe78 54 -or => [
55 -and => [
56 artist => { 'like', '%Smashing Pumpkins%' },
57 title => 'Siamese Dream',
58 ],
59 artist => 'Starchildren',
60 ],
61 });
40dbc108 62
63This results in the following C<WHERE> clause:
64
35d4fe78 65 WHERE ( artist LIKE '%Smashing Pumpkins%' AND title = 'Siamese Dream' )
66 OR artist = 'Starchildren'
40dbc108 67
68For more information on generating complex queries, see
69L<SQL::Abstract/WHERE CLAUSES>.
ee38fa40 70
d2f3e87b 71=head2 Arbitrary SQL through a custom ResultSource
321d9634 72
73Sometimes you have to run arbitrary SQL because your query is too complex
74(e.g. it contains Unions, Sub-Selects, Stored Procedures, etc.) or has to
75be optimized for your database in a special way, but you still want to
76get the results as a L<DBIx::Class::ResultSet>.
77The recommended way to accomplish this is by defining a separate ResultSource
78for your query. You can then inject complete SQL statements using a scalar
79reference (this is a feature of L<SQL::Abstract>).
80
81Say you want to run a complex custom query on your user data, here's what
82you have to add to your User class:
83
84 package My::Schema::User;
85
86 use base qw/DBIx::Class/;
87
88 # ->load_components, ->table, ->add_columns, etc.
89
90 # Make a new ResultSource based on the User class
91 my $source = __PACKAGE__->result_source_instance();
92 my $new_source = $source->new( $source );
93 $new_source->source_name( 'UserFriendsComplex' );
94
95 # Hand in your query as a scalar reference
96 # It will be added as a sub-select after FROM,
97 # so pay attention to the surrounding brackets!
98 $new_source->name( \<<SQL );
99 ( SELECT u.* FROM user u
100 INNER JOIN user_friends f ON u.id = f.user_id
101 WHERE f.friend_user_id = ?
102 UNION
103 SELECT u.* FROM user u
104 INNER JOIN user_friends f ON u.id = f.friend_user_id
105 WHERE f.user_id = ? )
106 SQL
107
108 # Finally, register your new ResultSource with your Schema
109 My::Schema->register_source( 'UserFriendsComplex' => $new_source );
110
111Next, you can execute your complex query using bind parameters like this:
112
113 my $friends = [ $schema->resultset( 'UserFriendsComplex' )->search( {},
114 {
115 bind => [ 12345, 12345 ]
116 }
117 ) ];
118
119... and you'll get back a perfect L<DBIx::Class::ResultSet>.
120
d2f3e87b 121=head2 Using specific columns
faf62551 122
324572ca 123When you only want specific columns from a table, you can use
124C<columns> to specify which ones you need. This is useful to avoid
125loading columns with large amounts of data that you aren't about to
126use anyway:
faf62551 127
bade79c4 128 my $rs = $schema->resultset('Artist')->search(
5e8b1b2a 129 undef,
bade79c4 130 {
5e8b1b2a 131 columns => [qw/ name /]
bade79c4 132 }
133 );
faf62551 134
bade79c4 135 # Equivalent SQL:
136 # SELECT artist.name FROM artist
faf62551 137
324572ca 138This is a shortcut for C<select> and C<as>, see below. C<columns>
139cannot be used together with C<select> and C<as>.
140
d2f3e87b 141=head2 Using database functions or stored procedures
faf62551 142
bade79c4 143The combination of C<select> and C<as> can be used to return the result of a
144database function or stored procedure as a column value. You use C<select> to
145specify the source for your column value (e.g. a column name, function, or
146stored procedure name). You then use C<as> to set the column name you will use
147to access the returned value:
faf62551 148
bade79c4 149 my $rs = $schema->resultset('Artist')->search(
324572ca 150 {},
bade79c4 151 {
152 select => [ 'name', { LENGTH => 'name' } ],
153 as => [qw/ name name_length /],
154 }
155 );
faf62551 156
bade79c4 157 # Equivalent SQL:
98b65433 158 # SELECT name name, LENGTH( name )
bade79c4 159 # FROM artist
faf62551 160
d676881f 161Note that the C< as > attribute has absolutely nothing to with the sql
162syntax C< SELECT foo AS bar > (see the documentation in
163L<DBIx::Class::ResultSet/ATTRIBUTES>). If your alias exists as a
164column in your base class (i.e. it was added with C<add_columns>), you
165just access it as normal. Our C<Artist> class has a C<name> column, so
166we just use the C<name> accessor:
faf62551 167
bade79c4 168 my $artist = $rs->first();
169 my $name = $artist->name();
faf62551 170
171If on the other hand the alias does not correspond to an existing column, you
324572ca 172have to fetch the value using the C<get_column> accessor:
faf62551 173
bade79c4 174 my $name_length = $artist->get_column('name_length');
faf62551 175
bade79c4 176If you don't like using C<get_column>, you can always create an accessor for
faf62551 177any of your aliases using either of these:
178
bade79c4 179 # Define accessor manually:
180 sub name_length { shift->get_column('name_length'); }
faf62551 181
bade79c4 182 # Or use DBIx::Class::AccessorGroup:
183 __PACKAGE__->mk_group_accessors('column' => 'name_length');
faf62551 184
d2f3e87b 185=head2 SELECT DISTINCT with multiple columns
faf62551 186
bade79c4 187 my $rs = $schema->resultset('Foo')->search(
324572ca 188 {},
bade79c4 189 {
190 select => [
191 { distinct => [ $source->columns ] }
192 ],
d676881f 193 as => [ $source->columns ] # remember 'as' is not the same as SQL AS :-)
bade79c4 194 }
195 );
faf62551 196
d2f3e87b 197=head2 SELECT COUNT(DISTINCT colname)
6607ee1b 198
bade79c4 199 my $rs = $schema->resultset('Foo')->search(
324572ca 200 {},
bade79c4 201 {
202 select => [
203 { count => { distinct => 'colname' } }
204 ],
205 as => [ 'count' ]
206 }
207 );
6607ee1b 208
3d565896 209 my $count = $rs->next->get_column('count');
210
d2f3e87b 211=head2 Grouping results
bade79c4 212
213L<DBIx::Class> supports C<GROUP BY> as follows:
214
215 my $rs = $schema->resultset('Artist')->search(
324572ca 216 {},
bade79c4 217 {
218 join => [qw/ cds /],
51458a6a 219 select => [ 'name', { count => 'cds.id' } ],
bade79c4 220 as => [qw/ name cd_count /],
221 group_by => [qw/ name /]
222 }
223 );
6607ee1b 224
bade79c4 225 # Equivalent SQL:
51458a6a 226 # SELECT name, COUNT( cd.id ) FROM artist
227 # LEFT JOIN cd ON artist.id = cd.artist
bade79c4 228 # GROUP BY name
6607ee1b 229
d676881f 230Please see L<DBIx::Class::ResultSet/ATTRIBUTES> documentation if you
231are in any way unsure about the use of the attributes above (C< join
232>, C< select >, C< as > and C< group_by >).
233
d2f3e87b 234=head2 Predefined searches
74dc2edc 235
324572ca 236You can write your own L<DBIx::Class::ResultSet> class by inheriting from it
74dc2edc 237and define often used searches as methods:
238
239 package My::DBIC::ResultSet::CD;
240 use strict;
241 use warnings;
242 use base 'DBIx::Class::ResultSet';
243
244 sub search_cds_ordered {
245 my ($self) = @_;
246
247 return $self->search(
248 {},
249 { order_by => 'name DESC' },
250 );
251 }
252
253 1;
254
255To use your resultset, first tell DBIx::Class to create an instance of it
256for you, in your My::DBIC::Schema::CD class:
257
9dc1bfce 258 # class definition as normal
259 __PACKAGE__->load_components(qw/ Core /);
260 __PACKAGE__->table('cd');
261
262 # tell DBIC to use the custom ResultSet class
74dc2edc 263 __PACKAGE__->resultset_class('My::DBIC::ResultSet::CD');
264
9dc1bfce 265Note that C<resultset_class> must be called after C<load_components> and C<table>, or you will get errors about missing methods.
266
74dc2edc 267Then call your new method in your code:
268
269 my $ordered_cds = $schema->resultset('CD')->search_cds_ordered();
270
d2f3e87b 271=head2 Using SQL functions on the left hand side of a comparison
1c133e22 272
273Using SQL functions on the left hand side of a comparison is generally
274not a good idea since it requires a scan of the entire table. However,
275it can be accomplished with C<DBIx::Class> when necessary.
276
277If you do not have quoting on, simply include the function in your search
278specification as you would any column:
279
280 $rs->search({ 'YEAR(date_of_birth)' => 1979 });
281
282With quoting on, or for a more portable solution, use the C<where>
283attribute:
284
285 $rs->search({}, { where => \'YEAR(date_of_birth) = 1979' });
286
287=begin hidden
288
289(When the bind args ordering bug is fixed, this technique will be better
290and can replace the one above.)
291
292With quoting on, or for a more portable solution, use the C<where> and
293C<bind> attributes:
294
295 $rs->search({}, {
296 where => \'YEAR(date_of_birth) = ?',
297 bind => [ 1979 ]
298 });
299
300=end hidden
301
d2f3e87b 302=head1 JOINS AND PREFETCHING
303
87980de7 304=head2 Using joins and prefetch
305
bade79c4 306You can use the C<join> attribute to allow searching on, or sorting your
307results by, one or more columns in a related table. To return all CDs matching
308a particular artist name:
ea6309e2 309
bade79c4 310 my $rs = $schema->resultset('CD')->search(
311 {
312 'artist.name' => 'Bob Marley'
313 },
314 {
51458a6a 315 join => 'artist', # join the artist table
bade79c4 316 }
317 );
318
319 # Equivalent SQL:
320 # SELECT cd.* FROM cd
321 # JOIN artist ON cd.artist = artist.id
322 # WHERE artist.name = 'Bob Marley'
323
324If required, you can now sort on any column in the related tables by including
325it in your C<order_by> attribute:
326
327 my $rs = $schema->resultset('CD')->search(
328 {
329 'artist.name' => 'Bob Marley'
330 },
331 {
51458a6a 332 join => 'artist',
bade79c4 333 order_by => [qw/ artist.name /]
334 }
2f81ed0f 335 );
ea6309e2 336
bade79c4 337 # Equivalent SQL:
338 # SELECT cd.* FROM cd
339 # JOIN artist ON cd.artist = artist.id
340 # WHERE artist.name = 'Bob Marley'
341 # ORDER BY artist.name
ea6309e2 342
bade79c4 343Note that the C<join> attribute should only be used when you need to search or
344sort using columns in a related table. Joining related tables when you only
345need columns from the main table will make performance worse!
ea6309e2 346
bade79c4 347Now let's say you want to display a list of CDs, each with the name of the
348artist. The following will work fine:
ea6309e2 349
bade79c4 350 while (my $cd = $rs->next) {
351 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
352 }
ea6309e2 353
bade79c4 354There is a problem however. We have searched both the C<cd> and C<artist> tables
355in our main query, but we have only returned data from the C<cd> table. To get
356the artist name for any of the CD objects returned, L<DBIx::Class> will go back
357to the database:
ea6309e2 358
bade79c4 359 SELECT artist.* FROM artist WHERE artist.id = ?
ea6309e2 360
361A statement like the one above will run for each and every CD returned by our
362main query. Five CDs, five extra queries. A hundred CDs, one hundred extra
363queries!
364
bade79c4 365Thankfully, L<DBIx::Class> has a C<prefetch> attribute to solve this problem.
897342e4 366This allows you to fetch results from related tables in advance:
ea6309e2 367
bade79c4 368 my $rs = $schema->resultset('CD')->search(
369 {
370 'artist.name' => 'Bob Marley'
371 },
372 {
51458a6a 373 join => 'artist',
bade79c4 374 order_by => [qw/ artist.name /],
51458a6a 375 prefetch => 'artist' # return artist data too!
bade79c4 376 }
377 );
ea6309e2 378
bade79c4 379 # Equivalent SQL (note SELECT from both "cd" and "artist"):
380 # SELECT cd.*, artist.* FROM cd
381 # JOIN artist ON cd.artist = artist.id
382 # WHERE artist.name = 'Bob Marley'
383 # ORDER BY artist.name
ea6309e2 384
385The code to print the CD list remains the same:
386
bade79c4 387 while (my $cd = $rs->next) {
388 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
389 }
ea6309e2 390
bade79c4 391L<DBIx::Class> has now prefetched all matching data from the C<artist> table,
ea6309e2 392so no additional SQL statements are executed. You now have a much more
393efficient query.
394
77d6b403 395Note that as of L<DBIx::Class> 0.05999_01, C<prefetch> I<can> be used with
396C<has_many> relationships.
ea6309e2 397
bade79c4 398Also note that C<prefetch> should only be used when you know you will
ea6309e2 399definitely use data from a related table. Pre-fetching related tables when you
400only need columns from the main table will make performance worse!
401
51458a6a 402=head2 Multiple joins
403
404In the examples above, the C<join> attribute was a scalar. If you
405pass an array reference instead, you can join to multiple tables. In
406this example, we want to limit the search further, using
407C<LinerNotes>:
408
409 # Relationships defined elsewhere:
410 # CD->belongs_to('artist' => 'Artist');
411 # CD->has_one('liner_notes' => 'LinerNotes', 'cd');
412 my $rs = $schema->resultset('CD')->search(
413 {
414 'artist.name' => 'Bob Marley'
415 'liner_notes.notes' => { 'like', '%some text%' },
416 },
417 {
418 join => [qw/ artist liner_notes /],
419 order_by => [qw/ artist.name /],
420 }
421 );
422
423 # Equivalent SQL:
424 # SELECT cd.*, artist.*, liner_notes.* FROM cd
425 # JOIN artist ON cd.artist = artist.id
426 # JOIN liner_notes ON cd.id = liner_notes.cd
427 # WHERE artist.name = 'Bob Marley'
428 # ORDER BY artist.name
429
d2f3e87b 430=head2 Multi-step joins
ea6309e2 431
432Sometimes you want to join more than one relationship deep. In this example,
bade79c4 433we want to find all C<Artist> objects who have C<CD>s whose C<LinerNotes>
434contain a specific string:
435
436 # Relationships defined elsewhere:
437 # Artist->has_many('cds' => 'CD', 'artist');
438 # CD->has_one('liner_notes' => 'LinerNotes', 'cd');
439
440 my $rs = $schema->resultset('Artist')->search(
441 {
442 'liner_notes.notes' => { 'like', '%some text%' },
443 },
444 {
445 join => {
446 'cds' => 'liner_notes'
447 }
448 }
449 );
ea6309e2 450
bade79c4 451 # Equivalent SQL:
452 # SELECT artist.* FROM artist
51458a6a 453 # LEFT JOIN cd ON artist.id = cd.artist
454 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
bade79c4 455 # WHERE liner_notes.notes LIKE '%some text%'
ea6309e2 456
457Joins can be nested to an arbitrary level. So if we decide later that we
458want to reduce the number of Artists returned based on who wrote the liner
459notes:
460
bade79c4 461 # Relationship defined elsewhere:
462 # LinerNotes->belongs_to('author' => 'Person');
463
464 my $rs = $schema->resultset('Artist')->search(
465 {
466 'liner_notes.notes' => { 'like', '%some text%' },
467 'author.name' => 'A. Writer'
468 },
469 {
470 join => {
471 'cds' => {
472 'liner_notes' => 'author'
ea6309e2 473 }
bade79c4 474 }
475 }
476 );
ea6309e2 477
bade79c4 478 # Equivalent SQL:
479 # SELECT artist.* FROM artist
51458a6a 480 # LEFT JOIN cd ON artist.id = cd.artist
481 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
482 # LEFT JOIN author ON author.id = liner_notes.author
bade79c4 483 # WHERE liner_notes.notes LIKE '%some text%'
484 # AND author.name = 'A. Writer'
87980de7 485
51458a6a 486=head2 Multi-step and multiple joins
487
488With various combinations of array and hash references, you can join
489tables in any combination you desire. For example, to join Artist to
490CD and Concert, and join CD to LinerNotes:
491
492 # Relationships defined elsewhere:
493 # Artist->has_many('concerts' => 'Concert', 'artist');
494
495 my $rs = $schema->resultset('Artist')->search(
496 { },
497 {
498 join => [
499 {
500 cds => 'liner_notes'
501 },
502 'concerts'
503 ],
504 }
505 );
506
507 # Equivalent SQL:
508 # SELECT artist.* FROM artist
509 # LEFT JOIN cd ON artist.id = cd.artist
510 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
511 # LEFT JOIN concert ON artist.id = concert.artist
512
897342e4 513=head2 Multi-step prefetch
514
515From 0.04999_05 onwards, C<prefetch> can be nested more than one relationship
516deep using the same syntax as a multi-step join:
517
518 my $rs = $schema->resultset('Tag')->search(
ac2803ef 519 {},
897342e4 520 {
521 prefetch => {
522 cd => 'artist'
523 }
524 }
525 );
526
527 # Equivalent SQL:
528 # SELECT tag.*, cd.*, artist.* FROM tag
51458a6a 529 # JOIN cd ON tag.cd = cd.id
530 # JOIN artist ON cd.artist = artist.id
897342e4 531
532Now accessing our C<cd> and C<artist> relationships does not need additional
533SQL statements:
534
535 my $tag = $rs->first;
536 print $tag->cd->artist->name;
537
d2f3e87b 538=head1 ROW-LEVEL OPERATIONS
539
540=head2 Retrieving a row object's Schema
541
542It is possible to get a Schema object from a row object like so:
543
544 my $schema = $cd->result_source->schema;
545 # use the schema as normal:
546 my $artist_rs = $schema->resultset('Artist');
547
548This can be useful when you don't want to pass around a Schema object to every
549method.
550
551=head2 Getting the value of the primary key for the last database insert
552
553AKA getting last_insert_id
554
555If you are using PK::Auto (which is a core component as of 0.07), this is
556straightforward:
557
558 my $foo = $rs->create(\%blah);
559 # do more stuff
560 my $id = $foo->id; # foo->my_primary_key_field will also work.
561
562If you are not using autoincrementing primary keys, this will probably
563not work, but then you already know the value of the last primary key anyway.
564
565=head2 Stringification
566
567Employ the standard stringification technique by using the C<overload>
568module.
569
570To make an object stringify itself as a single column, use something
571like this (replace C<foo> with the column/method of your choice):
572
573 use overload '""' => sub { shift->name}, fallback => 1;
574
575For more complex stringification, you can use an anonymous subroutine:
576
577 use overload '""' => sub { $_[0]->name . ", " .
578 $_[0]->address }, fallback => 1;
579
580=head3 Stringification Example
581
582Suppose we have two tables: C<Product> and C<Category>. The table
583specifications are:
584
585 Product(id, Description, category)
586 Category(id, Description)
587
588C<category> is a foreign key into the Category table.
589
590If you have a Product object C<$obj> and write something like
591
592 print $obj->category
593
594things will not work as expected.
595
596To obtain, for example, the category description, you should add this
597method to the class defining the Category table:
598
599 use overload "" => sub {
600 my $self = shift;
601
602 return $self->Description;
603 }, fallback => 1;
604
605=head2 Want to know if find_or_create found or created a row?
606
607Just use C<find_or_new> instead, then check C<in_storage>:
608
609 my $obj = $rs->find_or_new({ blah => 'blarg' });
610 unless ($obj->in_storage) {
611 $obj->insert;
612 # do whatever else you wanted if it was a new row
613 }
614
615=head2 Dynamic Sub-classing DBIx::Class proxy classes
616
617AKA multi-class object inflation from one table
618
619L<DBIx::Class> classes are proxy classes, therefore some different
620techniques need to be employed for more than basic subclassing. In
621this example we have a single user table that carries a boolean bit
622for admin. We would like like to give the admin users
623objects(L<DBIx::Class::Row>) the same methods as a regular user but
624also special admin only methods. It doesn't make sense to create two
625seperate proxy-class files for this. We would be copying all the user
626methods into the Admin class. There is a cleaner way to accomplish
627this.
628
629Overriding the C<inflate_result> method within the User proxy-class
630gives us the effect we want. This method is called by
631L<DBIx::Class::ResultSet> when inflating a result from storage. So we
632grab the object being returned, inspect the values we are looking for,
633bless it if it's an admin object, and then return it. See the example
634below:
635
636B<Schema Definition>
637
638 package DB::Schema;
639
640 use base qw/DBIx::Class::Schema/;
641
642 __PACKAGE__->load_classes(qw/User/);
643
644
645B<Proxy-Class definitions>
646
647 package DB::Schema::User;
648
649 use strict;
650 use warnings;
651 use base qw/DBIx::Class/;
652
653 ### Defined what our admin class is for ensure_class_loaded
654 my $admin_class = __PACKAGE__ . '::Admin';
655
656 __PACKAGE__->load_components(qw/Core/);
657
658 __PACKAGE__->table('users');
659
660 __PACKAGE__->add_columns(qw/user_id email password
661 firstname lastname active
662 admin/);
663
664 __PACKAGE__->set_primary_key('user_id');
665
666 sub inflate_result {
667 my $self = shift;
668 my $ret = $self->next::method(@_);
669 if( $ret->admin ) {### If this is an admin rebless for extra functions
670 $self->ensure_class_loaded( $admin_class );
671 bless $ret, $admin_class;
672 }
673 return $ret;
674 }
675
676 sub hello {
677 print "I am a regular user.\n";
678 return ;
679 }
680
681
682 package DB::Schema::User::Admin;
683
684 use strict;
685 use warnings;
686 use base qw/DB::Schema::User/;
687
688 sub hello
689 {
690 print "I am an admin.\n";
691 return;
692 }
693
694 sub do_admin_stuff
695 {
696 print "I am doing admin stuff\n";
697 return ;
698 }
699
700B<Test File> test.pl
701
702 use warnings;
703 use strict;
704 use DB::Schema;
705
706 my $user_data = { email => 'someguy@place.com',
707 password => 'pass1',
708 admin => 0 };
709
710 my $admin_data = { email => 'someadmin@adminplace.com',
711 password => 'pass2',
712 admin => 1 };
713
714 my $schema = DB::Schema->connection('dbi:Pg:dbname=test');
715
716 $schema->resultset('User')->create( $user_data );
717 $schema->resultset('User')->create( $admin_data );
718
719 ### Now we search for them
720 my $user = $schema->resultset('User')->single( $user_data );
721 my $admin = $schema->resultset('User')->single( $admin_data );
722
723 print ref $user, "\n";
724 print ref $admin, "\n";
725
726 print $user->password , "\n"; # pass1
727 print $admin->password , "\n";# pass2; inherited from User
728 print $user->hello , "\n";# I am a regular user.
729 print $admin->hello, "\n";# I am an admin.
730
731 ### The statement below will NOT print
732 print "I can do admin stuff\n" if $user->can('do_admin_stuff');
733 ### The statement below will print
734 print "I can do admin stuff\n" if $admin->can('do_admin_stuff');
735
a5b29361 736=head2 Skip row object creation for faster results
d2f3e87b 737
738DBIx::Class is not built for speed, it's built for convenience and
739ease of use, but sometimes you just need to get the data, and skip the
740fancy objects.
741
742To do this simply use L<DBIx::Class::ResultClass::HashRefInflator>.
743
744 my $rs = $schema->resultset('CD');
745
746 $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
747
748 my $hash_ref = $rs->find(1);
a5b29361 749
d2f3e87b 750Wasn't that easy?
751
752=head2 Get raw data for blindingly fast results
753
754If the L<HashRefInflator|DBIx::Class::ResultClass::HashRefInflator> solution
755above is not fast enough for you, you can use a DBIx::Class to return values
756exactly as they come out of the data base with none of the convenience methods
757wrapped round them.
758
759This is used like so:-
760
761 my $cursor = $rs->cursor
762 while (my @vals = $cursor->next) {
763 # use $val[0..n] here
764 }
765
766You will need to map the array offsets to particular columns (you can
767use the I<select> attribute of C<search()> to force ordering).
768
769=head1 RESULTSET OPERATIONS
770
771=head2 Getting Schema from a ResultSet
772
773To get the schema object from a result set, do the following:
774
775 $rs->result_source->schema
776
777=head2 Getting Columns Of Data
778
779AKA Aggregating Data
ac2803ef 780
781If you want to find the sum of a particular column there are several
782ways, the obvious one is to use search:
783
784 my $rs = $schema->resultset('Items')->search(
785 {},
786 {
787 select => [ { sum => 'Cost' } ],
d676881f 788 as => [ 'total_cost' ], # remember this 'as' is for DBIx::Class::ResultSet not SQL
ac2803ef 789 }
790 );
791 my $tc = $rs->first->get_column('total_cost');
792
793Or, you can use the L<DBIx::Class::ResultSetColumn>, which gets
794returned when you ask the C<ResultSet> for a column using
795C<get_column>:
796
797 my $cost = $schema->resultset('Items')->get_column('Cost');
798 my $tc = $cost->sum;
799
800With this you can also do:
801
802 my $minvalue = $cost->min;
803 my $maxvalue = $cost->max;
804
805Or just iterate through the values of this column only:
806
807 while ( my $c = $cost->next ) {
808 print $c;
809 }
810
811 foreach my $c ($cost->all) {
812 print $c;
813 }
814
709353af 815C<ResultSetColumn> only has a limited number of built-in functions, if
816you need one that it doesn't have, then you can use the C<func> method
817instead:
818
819 my $avg = $cost->func('AVERAGE');
820
821This will cause the following SQL statement to be run:
822
823 SELECT AVERAGE(Cost) FROM Items me
824
825Which will of course only work if your database supports this function.
ac2803ef 826See L<DBIx::Class::ResultSetColumn> for more documentation.
827
204e5c03 828=head2 Creating a result set from a set of rows
829
830Sometimes you have a (set of) row objects that you want to put into a
831resultset without the need to hit the DB again. You can do that by using the
832L<set_cache|DBIx::Class::Resultset/set_cache> method:
833
2d7a4e46 834 my @uploadable_groups;
204e5c03 835 while (my $group = $groups->next) {
836 if ($group->can_upload($self)) {
837 push @uploadable_groups, $group;
838 }
839 }
840 my $new_rs = $self->result_source->resultset;
841 $new_rs->set_cache(\@uploadable_groups);
842 return $new_rs;
843
844
d2f3e87b 845=head1 USING RELATIONSHIPS
acee4e4d 846
d2f3e87b 847=head2 Create a new row in a related table
acee4e4d 848
6f1434fd 849 my $author = $book->create_related('author', { name => 'Fred'});
acee4e4d 850
d2f3e87b 851=head2 Search in a related table
acee4e4d 852
853Only searches for books named 'Titanic' by the author in $author.
854
6f1434fd 855 my $books_rs = $author->search_related('books', { name => 'Titanic' });
acee4e4d 856
d2f3e87b 857=head2 Delete data in a related table
acee4e4d 858
859Deletes only the book named Titanic by the author in $author.
860
6f1434fd 861 $author->delete_related('books', { name => 'Titanic' });
acee4e4d 862
d2f3e87b 863=head2 Ordering a relationship result set
f8bad769 864
865If you always want a relation to be ordered, you can specify this when you
866create the relationship.
867
6f1434fd 868To order C<< $book->pages >> by descending page_number, create the relation
869as follows:
f8bad769 870
6f1434fd 871 __PACKAGE__->has_many('pages' => 'Page', 'book', { order_by => \'page_number DESC'} );
f8bad769 872
d2f3e87b 873=head2 Many-to-many relationships
f8bad769 874
d2f3e87b 875This is straightforward using L<ManyToMany|DBIx::Class::Relationship/many_to_many>:
f8bad769 876
d2f3e87b 877 package My::User;
6f1434fd 878 use base 'DBIx::Class';
879 __PACKAGE__->load_components('Core');
d2f3e87b 880 __PACKAGE__->table('user');
881 __PACKAGE__->add_columns(qw/id name/);
882 __PACKAGE__->set_primary_key('id');
883 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'user');
884 __PACKAGE__->many_to_many('addresses' => 'user_address', 'address');
87980de7 885
d2f3e87b 886 package My::UserAddress;
6f1434fd 887 use base 'DBIx::Class';
888 __PACKAGE__->load_components('Core');
d2f3e87b 889 __PACKAGE__->table('user_address');
890 __PACKAGE__->add_columns(qw/user address/);
891 __PACKAGE__->set_primary_key(qw/user address/);
892 __PACKAGE__->belongs_to('user' => 'My::User');
893 __PACKAGE__->belongs_to('address' => 'My::Address');
181a28f4 894
d2f3e87b 895 package My::Address;
6f1434fd 896 use base 'DBIx::Class';
897 __PACKAGE__->load_components('Core');
d2f3e87b 898 __PACKAGE__->table('address');
899 __PACKAGE__->add_columns(qw/id street town area_code country/);
900 __PACKAGE__->set_primary_key('id');
901 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'address');
902 __PACKAGE__->many_to_many('users' => 'user_address', 'user');
903
904 $rs = $user->addresses(); # get all addresses for a user
905 $rs = $address->users(); # get all users for an address
906
907=head1 TRANSACTIONS
908
909As of version 0.04001, there is improved transaction support in
910L<DBIx::Class::Storage> and L<DBIx::Class::Schema>. Here is an
911example of the recommended way to use it:
912
913 my $genus = $schema->resultset('Genus')->find(12);
914
915 my $coderef2 = sub {
916 $genus->extinct(1);
917 $genus->update;
918 };
70634260 919
181a28f4 920 my $coderef1 = sub {
35d4fe78 921 $genus->add_to_species({ name => 'troglodyte' });
922 $genus->wings(2);
923 $genus->update;
6f1434fd 924 $schema->txn_do($coderef2); # Can have a nested transaction. Only the outer will actualy commit
181a28f4 925 return $genus->species;
926 };
927
181a28f4 928 my $rs;
929 eval {
70634260 930 $rs = $schema->txn_do($coderef1);
181a28f4 931 };
932
933 if ($@) { # Transaction failed
934 die "the sky is falling!" #
935 if ($@ =~ /Rollback failed/); # Rollback failed
936
937 deal_with_failed_transaction();
35d4fe78 938 }
87980de7 939
181a28f4 940Nested transactions will work as expected. That is, only the outermost
941transaction will actually issue a commit to the $dbh, and a rollback
942at any level of any transaction will cause the entire nested
943transaction to fail. Support for savepoints and for true nested
40dbc108 944transactions (for databases that support them) will hopefully be added
945in the future.
ee38fa40 946
d2f3e87b 947=head1 SQL
ee38fa40 948
d2f3e87b 949=head2 Creating Schemas From An Existing Database
ea6309e2 950
d2f3e87b 951L<DBIx::Class::Schema::Loader> will connect to a database and create a
952L<DBIx::Class::Schema> and associated sources by examining the database.
bade79c4 953
d2f3e87b 954The recommend way of achieving this is to use the
955L<make_schema_at|DBIx::Class::Schema::Loader/make_schema_at> method:
bade79c4 956
6f1434fd 957 perl -MDBIx::Class::Schema::Loader=make_schema_at,dump_to_dir:./lib \
958 -e 'make_schema_at("My::Schema", { debug => 1 }, [ "dbi:Pg:dbname=foo","postgres" ])'
362500af 959
d2f3e87b 960This will create a tree of files rooted at C<./lib/My/Schema/> containing
961source definitions for all the tables found in the C<foo> database.
362500af 962
d2f3e87b 963=head2 Creating DDL SQL
362500af 964
264f1571 965The following functionality requires you to have L<SQL::Translator>
966(also known as "SQL Fairy") installed.
362500af 967
264f1571 968To create a set of database-specific .sql files for the above schema:
362500af 969
264f1571 970 my $schema = My::Schema->connect($dsn);
971 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
972 '0.1',
d2f3e87b 973 './dbscriptdir/'
264f1571 974 );
975
976By default this will create schema files in the current directory, for
977MySQL, SQLite and PostgreSQL, using the $VERSION from your Schema.pm.
978
979To create a new database using the schema:
980
981 my $schema = My::Schema->connect($dsn);
982 $schema->deploy({ add_drop_tables => 1});
983
984To import created .sql files using the mysql client:
985
986 mysql -h "host" -D "database" -u "user" -p < My_Schema_1.0_MySQL.sql
987
988To create C<ALTER TABLE> conversion scripts to update a database to a
989newer version of your schema at a later point, first set a new
d2f3e87b 990C<$VERSION> in your Schema file, then:
264f1571 991
992 my $schema = My::Schema->connect($dsn);
993 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
994 '0.2',
995 '/dbscriptdir/',
996 '0.1'
997 );
998
999This will produce new database-specific .sql files for the new version
1000of the schema, plus scripts to convert from version 0.1 to 0.2. This
1001requires that the files for 0.1 as created above are available in the
1002given directory to diff against.
362500af 1003
6f1434fd 1004=head2 Select from dual
16cd5b28 1005
1006Dummy tables are needed by some databases to allow calling functions
1007or expressions that aren't based on table content, for examples of how
1008this applies to various database types, see:
1009L<http://troels.arvin.dk/db/rdbms/#other-dummy_table>.
1010
1011Note: If you're using Oracles dual table don't B<ever> do anything
1012other than a select, if you CRUD on your dual table you *will* break
1013your database.
1014
1015Make a table class as you would for any other table
1016
1017 package MyAppDB::Dual;
1018 use strict;
1019 use warnings;
1020 use base 'DBIx::Class';
1021 __PACKAGE__->load_components("Core");
1022 __PACKAGE__->table("Dual");
1023 __PACKAGE__->add_columns(
1024 "dummy",
1025 { data_type => "VARCHAR2", is_nullable => 0, size => 1 },
1026 );
1027
1028Once you've loaded your table class select from it using C<select>
1029and C<as> instead of C<columns>
1030
1031 my $rs = $schema->resultset('Dual')->search(undef,
1032 { select => [ 'sydate' ],
1033 as => [ 'now' ]
1034 },
1035 );
1036
1037All you have to do now is be careful how you access your resultset, the below
1038will not work because there is no column called 'now' in the Dual table class
1039
1040 while (my $dual = $rs->next) {
1041 print $dual->now."\n";
1042 }
6f1434fd 1043 # Can't locate object method "now" via package "MyAppDB::Dual" at headshot.pl line 23.
16cd5b28 1044
1045You could of course use 'dummy' in C<as> instead of 'now', or C<add_columns> to
1046your Dual class for whatever you wanted to select from dual, but that's just
1047silly, instead use C<get_column>
1048
1049 while (my $dual = $rs->next) {
1050 print $dual->get_column('now')."\n";
1051 }
1052
1053Or use C<cursor>
1054
1055 my $cursor = $rs->cursor;
1056 while (my @vals = $cursor->next) {
1057 print $vals[0]."\n";
1058 }
1059
1060Or use L<DBIx::Class::ResultClass::HashRefInflator>
1061
1062 $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
1063 while ( my $dual = $rs->next ) {
1064 print $dual->{now}."\n";
1065 }
1066
1067Here are some example C<select> conditions to illustrate the different syntax
1068you could use for doing stuff like
1069C<oracles.heavily(nested(functions_can('take', 'lots'), OF), 'args')>
1070
1071 # get a sequence value
1072 select => [ 'A_SEQ.nextval' ],
1073
1074 # get create table sql
1075 select => [ { 'dbms_metadata.get_ddl' => [ "'TABLE'", "'ARTIST'" ]} ],
1076
1077 # get a random num between 0 and 100
1078 select => [ { "trunc" => [ { "dbms_random.value" => [0,100] } ]} ],
1079
1080 # what year is it?
1081 select => [ { 'extract' => [ \'year from sysdate' ] } ],
1082
1083 # do some math
1084 select => [ {'round' => [{'cos' => [ \'180 * 3.14159265359/180' ]}]}],
1085
1086 # which day of the week were you born on?
6f1434fd 1087 select => [{'to_char' => [{'to_date' => [ "'25-DEC-1980'", "'dd-mon-yyyy'" ]}, "'day'"]}],
16cd5b28 1088
1089 # select 16 rows from dual
1090 select => [ "'hello'" ],
1091 as => [ 'world' ],
1092 group_by => [ 'cube( 1, 2, 3, 4 )' ],
1093
1094
1095
d2f3e87b 1096=head2 Adding Indexes And Functions To Your SQL
362500af 1097
d2f3e87b 1098Often you will want indexes on columns on your table to speed up searching. To
1099do this, create a method called C<sqlt_deploy_hook> in the relevant source
1100class:
b0a20454 1101
d2f3e87b 1102 package My::Schema::Artist;
b0a20454 1103
d2f3e87b 1104 __PACKAGE__->table('artist');
1105 __PACKAGE__->add_columns(id => { ... }, name => { ... })
b0a20454 1106
d2f3e87b 1107 sub sqlt_deploy_hook {
1108 my ($self, $sqlt_table) = @_;
1109
1110 $sqlt_table->add_index(name => 'idx_name', fields => ['name']);
1111 }
1112
1113 1;
1114
1115Sometimes you might want to change the index depending on the type of the
1116database for which SQL is being generated:
1117
1118 my ($db_type = $sqlt_table->schema->translator->producer_type)
1119 =~ s/^SQL::Translator::Producer:://;
1120
1121You can also add hooks to the schema level to stop certain tables being
1122created:
1123
1124 package My::Schema;
1125
1126 ...
1127
1128 sub sqlt_deploy_hook {
1129 my ($self, $sqlt_schema) = @_;
1130
1131 $sqlt_schema->drop_table('table_name');
1132 }
1133
1134You could also add views or procedures to the output using
1135L<SQL::Translator::Schema/add_view> or
1136L<SQL::Translator::Schema/add_procedure>.
b0a20454 1137
362500af 1138=head2 Schema versioning
1139
1140The following example shows simplistically how you might use DBIx::Class to
1141deploy versioned schemas to your customers. The basic process is as follows:
1142
da4779ad 1143=over 4
1144
1145=item 1.
1146
1147Create a DBIx::Class schema
1148
1149=item 2.
1150
1151Save the schema
1152
1153=item 3.
1154
1155Deploy to customers
1156
1157=item 4.
1158
1159Modify schema to change functionality
1160
1161=item 5.
1162
1163Deploy update to customers
1164
1165=back
362500af 1166
d2f3e87b 1167B<Create a DBIx::Class schema>
362500af 1168
1169This can either be done manually, or generated from an existing database as
d2f3e87b 1170described under L</Creating Schemas From An Existing Database>
362500af 1171
d2f3e87b 1172B<Save the schema>
362500af 1173
d2f3e87b 1174Call L<DBIx::Class::Schema/create_ddl_dir> as above under L</Creating DDL SQL>.
362500af 1175
d2f3e87b 1176B<Deploy to customers>
362500af 1177
1178There are several ways you could deploy your schema. These are probably
1179beyond the scope of this recipe, but might include:
1180
da4779ad 1181=over 4
1182
1183=item 1.
1184
1185Require customer to apply manually using their RDBMS.
1186
1187=item 2.
1188
1189Package along with your app, making database dump/schema update/tests
362500af 1190all part of your install.
1191
da4779ad 1192=back
1193
d2f3e87b 1194B<Modify the schema to change functionality>
362500af 1195
264f1571 1196As your application evolves, it may be necessary to modify your schema
1197to change functionality. Once the changes are made to your schema in
1198DBIx::Class, export the modified schema and the conversion scripts as
d2f3e87b 1199in L</Creating DDL SQL>.
362500af 1200
d2f3e87b 1201B<Deploy update to customers>
362500af 1202
264f1571 1203Add the L<DBIx::Class::Schema::Versioned> schema component to your
1204Schema class. This will add a new table to your database called
ecea7937 1205C<dbix_class_schema_vesion> which will keep track of which version is installed
264f1571 1206and warn if the user trys to run a newer schema version than the
1207database thinks it has.
1208
1209Alternatively, you can send the conversion sql scripts to your
1210customers as above.
362500af 1211
d2f3e87b 1212=head2 Setting quoting for the generated SQL.
1213
1214If the database contains column names with spaces and/or reserved words, they
1215need to be quoted in the SQL queries. This is done using:
1216
1217 __PACKAGE__->storage->sql_maker->quote_char([ qw/[ ]/] );
1218 __PACKAGE__->storage->sql_maker->name_sep('.');
1219
1220The first sets the quote characters. Either a pair of matching
1221brackets, or a C<"> or C<'>:
1222
1223 __PACKAGE__->storage->sql_maker->quote_char('"');
1224
1225Check the documentation of your database for the correct quote
1226characters to use. C<name_sep> needs to be set to allow the SQL
1227generator to put the quotes the correct place.
1228
1229In most cases you should set these as part of the arguments passed to
1230L<DBIx::Class::Schema/conect>:
1231
1232 my $schema = My::Schema->connect(
1233 'dbi:mysql:my_db',
1234 'db_user',
1235 'db_password',
1236 {
1237 quote_char => '"',
1238 name_sep => '.'
1239 }
1240 )
1241
7be93b07 1242=head2 Setting limit dialect for SQL::Abstract::Limit
1243
324572ca 1244In some cases, SQL::Abstract::Limit cannot determine the dialect of
1245the remote SQL server by looking at the database handle. This is a
1246common problem when using the DBD::JDBC, since the DBD-driver only
1247know that in has a Java-driver available, not which JDBC driver the
1248Java component has loaded. This specifically sets the limit_dialect
1249to Microsoft SQL-server (See more names in SQL::Abstract::Limit
1250-documentation.
7be93b07 1251
1252 __PACKAGE__->storage->sql_maker->limit_dialect('mssql');
1253
324572ca 1254The JDBC bridge is one way of getting access to a MSSQL server from a platform
7be93b07 1255that Microsoft doesn't deliver native client libraries for. (e.g. Linux)
1256
d2f3e87b 1257The limit dialect can also be set at connect time by specifying a
1258C<limit_dialect> key in the final hash as shown above.
2437a1e3 1259
d2f3e87b 1260=head1 BOOTSTRAPPING/MIGRATING
2437a1e3 1261
d2f3e87b 1262=head2 Easy migration from class-based to schema-based setup
2437a1e3 1263
d2f3e87b 1264You want to start using the schema-based approach to L<DBIx::Class>
1265(see L<SchemaIntro.pod>), but have an established class-based setup with lots
1266of existing classes that you don't want to move by hand. Try this nifty script
1267instead:
1268
1269 use MyDB;
1270 use SQL::Translator;
1271
1272 my $schema = MyDB->schema_instance;
2437a1e3 1273
d2f3e87b 1274 my $translator = SQL::Translator->new(
1275 debug => $debug || 0,
1276 trace => $trace || 0,
1277 no_comments => $no_comments || 0,
1278 show_warnings => $show_warnings || 0,
1279 add_drop_table => $add_drop_table || 0,
1280 validate => $validate || 0,
1281 parser_args => {
1282 'DBIx::Schema' => $schema,
1283 },
1284 producer_args => {
1285 'prefix' => 'My::Schema',
1286 },
1287 );
1288
1289 $translator->parser('SQL::Translator::Parser::DBIx::Class');
1290 $translator->producer('SQL::Translator::Producer::DBIx::Class::File');
1291
1292 my $output = $translator->translate(@args) or die
1293 "Error: " . $translator->error;
1294
1295 print $output;
2437a1e3 1296
d2f3e87b 1297You could use L<Module::Find> to search for all subclasses in the MyDB::*
1298namespace, which is currently left as an exercise for the reader.
2437a1e3 1299
d2f3e87b 1300=head1 OVERLOADING METHODS
086b93a2 1301
ab872312 1302L<DBIx::Class> uses the L<Class::C3> package, which provides for redispatch of
1303method calls, useful for things like default values and triggers. You have to
1304use calls to C<next::method> to overload methods. More information on using
1305L<Class::C3> with L<DBIx::Class> can be found in
086b93a2 1306L<DBIx::Class::Manual::Component>.
1307
d2f3e87b 1308=head2 Setting default values for a row
1309
1310It's as simple as overriding the C<new> method. Note the use of
1311C<next::method>.
1312
1313 sub new {
1314 my ( $class, $attrs ) = @_;
1315
1316 $attrs->{foo} = 'bar' unless defined $attrs->{foo};
1317
1318 my $new = $class->next::method($attrs);
1319
1320 return $new;
1321 }
1322
1323For more information about C<next::method>, look in the L<Class::C3>
1324documentation. See also L<DBIx::Class::Manual::Component> for more
1325ways to write your own base classes to do this.
1326
1327People looking for ways to do "triggers" with DBIx::Class are probably
1328just looking for this.
1329
1330=head2 Changing one field whenever another changes
086b93a2 1331
1332For example, say that you have three columns, C<id>, C<number>, and
1333C<squared>. You would like to make changes to C<number> and have
1334C<squared> be automagically set to the value of C<number> squared.
1335You can accomplish this by overriding C<store_column>:
1336
1337 sub store_column {
1338 my ( $self, $name, $value ) = @_;
1339 if ($name eq 'number') {
1340 $self->squared($value * $value);
1341 }
1342 $self->next::method($name, $value);
1343 }
1344
1345Note that the hard work is done by the call to C<next::method>, which
324572ca 1346redispatches your call to store_column in the superclass(es).
086b93a2 1347
d2f3e87b 1348=head2 Automatically creating related objects
086b93a2 1349
324572ca 1350You might have a class C<Artist> which has many C<CD>s. Further, if you
086b93a2 1351want to create a C<CD> object every time you insert an C<Artist> object.
ccbebdbc 1352You can accomplish this by overriding C<insert> on your objects:
086b93a2 1353
1354 sub insert {
ccbebdbc 1355 my ( $self, @args ) = @_;
1356 $self->next::method(@args);
086b93a2 1357 $self->cds->new({})->fill_from_artist($self)->insert;
1358 return $self;
1359 }
1360
1361where C<fill_from_artist> is a method you specify in C<CD> which sets
1362values in C<CD> based on the data in the C<Artist> object you pass in.
1363
d2f3e87b 1364=head2 Wrapping/overloading a column accessor
1365
1366B<Problem:>
1367
1368Say you have a table "Camera" and want to associate a description
1369with each camera. For most cameras, you'll be able to generate the description from
1370the other columns. However, in a few special cases you may want to associate a
1371custom description with a camera.
1372
1373B<Solution:>
1374
1375In your database schema, define a description field in the "Camera" table that
1376can contain text and null values.
1377
1378In DBIC, we'll overload the column accessor to provide a sane default if no
1379custom description is defined. The accessor will either return or generate the
1380description, depending on whether the field is null or not.
1381
1382First, in your "Camera" schema class, define the description field as follows:
1383
1384 __PACKAGE__->add_columns(description => { accessor => '_description' });
1385
1386Next, we'll define the accessor-wrapper subroutine:
1387
1388 sub description {
1389 my $self = shift;
1390
1391 # If there is an update to the column, we'll let the original accessor
1392 # deal with it.
1393 return $self->_description(@_) if @_;
1394
1395 # Fetch the column value.
1396 my $description = $self->_description;
1397
1398 # If there's something in the description field, then just return that.
1399 return $description if defined $description && length $descripton;
1400
1401 # Otherwise, generate a description.
1402 return $self->generate_description;
1403 }
1404
1405=head1 DEBUGGING AND PROFILING
1406
1407=head2 DBIx::Class objects with Data::Dumper
1def3451 1408
1409L<Data::Dumper> can be a very useful tool for debugging, but sometimes it can
1410be hard to find the pertinent data in all the data it can generate.
1411Specifically, if one naively tries to use it like so,
1412
1413 use Data::Dumper;
1414
1415 my $cd = $schema->resultset('CD')->find(1);
1416 print Dumper($cd);
1417
1418several pages worth of data from the CD object's schema and result source will
1419be dumped to the screen. Since usually one is only interested in a few column
1420values of the object, this is not very helpful.
1421
1422Luckily, it is possible to modify the data before L<Data::Dumper> outputs
1423it. Simply define a hook that L<Data::Dumper> will call on the object before
1424dumping it. For example,
1425
1426 package My::DB::CD;
1427
1428 sub _dumper_hook {
99fb1058 1429 $_[0] = bless {
1430 %{ $_[0] },
1def3451 1431 result_source => undef,
99fb1058 1432 }, ref($_[0]);
1def3451 1433 }
1434
1435 [...]
1436
1437 use Data::Dumper;
1438
22139027 1439 local $Data::Dumper::Freezer = '_dumper_hook';
1def3451 1440
1441 my $cd = $schema->resultset('CD')->find(1);
1442 print Dumper($cd);
1443 # dumps $cd without its ResultSource
1444
1445If the structure of your schema is such that there is a common base class for
1446all your table classes, simply put a method similar to C<_dumper_hook> in the
1447base class and set C<$Data::Dumper::Freezer> to its name and L<Data::Dumper>
1448will automagically clean up your data before printing it. See
1449L<Data::Dumper/EXAMPLES> for more information.
1450
4c248161 1451=head2 Profiling
1452
85f78622 1453When you enable L<DBIx::Class::Storage>'s debugging it prints the SQL
4c248161 1454executed as well as notifications of query completion and transaction
1455begin/commit. If you'd like to profile the SQL you can subclass the
1456L<DBIx::Class::Storage::Statistics> class and write your own profiling
1457mechanism:
1458
1459 package My::Profiler;
1460 use strict;
1461
1462 use base 'DBIx::Class::Storage::Statistics';
1463
1464 use Time::HiRes qw(time);
1465
1466 my $start;
1467
1468 sub query_start {
1469 my $self = shift();
1470 my $sql = shift();
1471 my $params = @_;
1472
70f39278 1473 $self->print("Executing $sql: ".join(', ', @params)."\n");
4c248161 1474 $start = time();
1475 }
1476
1477 sub query_end {
1478 my $self = shift();
1479 my $sql = shift();
1480 my @params = @_;
1481
70f39278 1482 my $elapsed = sprintf("%0.4f", time() - $start);
1483 $self->print("Execution took $elapsed seconds.\n");
4c248161 1484 $start = undef;
1485 }
1486
1487 1;
1488
1489You can then install that class as the debugging object:
1490
70f39278 1491 __PACKAGE__->storage->debugobj(new My::Profiler());
1492 __PACKAGE__->storage->debug(1);
4c248161 1493
1494A more complicated example might involve storing each execution of SQL in an
1495array:
1496
1497 sub query_end {
1498 my $self = shift();
1499 my $sql = shift();
1500 my @params = @_;
1501
1502 my $elapsed = time() - $start;
1503 push(@{ $calls{$sql} }, {
1504 params => \@params,
1505 elapsed => $elapsed
1506 });
1507 }
1508
1509You could then create average, high and low execution times for an SQL
1510statement and dig down to see if certain parameters cause aberrant behavior.
70f39278 1511You might want to check out L<DBIx::Class::QueryLog> as well.
4c248161 1512
7aaec96c 1513
40dbc108 1514=cut