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