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