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