3 DBIx::Class::Manual::Cookbook - Miscellaneous recipes
9 When you expect a large number of results, you can ask L<DBIx::Class> for a
10 paged resultset, which will fetch only a defined number of records at a time:
12 my $rs = $schema->resultset('Artist')->search(
15 page => 1, # page to return (defaults to 1)
16 rows => 10, # number of results per page
20 return $rs->all(); # all records for page 1
22 return $rs->page(2); # records for page 2
24 You can get a L<Data::Page> object for the resultset (suitable for use
25 in e.g. a template) using the C<pager> method:
29 =head2 Complex WHERE clauses
31 Sometimes you need to formulate a query using specific operators:
33 my @albums = $schema->resultset('Album')->search({
34 artist => { 'like', '%Lamb%' },
35 title => { 'like', '%Fear of Fours%' },
38 This results in something like the following C<WHERE> clause:
40 WHERE artist LIKE ? AND title LIKE ?
42 And the following bind values for the placeholders: C<'%Lamb%'>, C<'%Fear of
45 Other queries might require slightly more complex logic:
47 my @albums = $schema->resultset('Album')->search({
50 artist => { 'like', '%Smashing Pumpkins%' },
51 title => 'Siamese Dream',
53 artist => 'Starchildren',
57 This results in the following C<WHERE> clause:
59 WHERE ( artist LIKE '%Smashing Pumpkins%' AND title = 'Siamese Dream' )
60 OR artist = 'Starchildren'
62 For more information on generating complex queries, see
63 L<SQL::Abstract/WHERE CLAUSES>.
65 =head2 Retrieve one and only one row from a resultset
67 Sometimes you need only the first "top" row of a resultset. While this
68 can be easily done with L<< $rs->first|DBIx::Class::ResultSet/first
69 >>, it is suboptimal, as a full blown cursor for the resultset will be
70 created and then immediately destroyed after fetching the first row
71 object. L<< $rs->single|DBIx::Class::ResultSet/single >> is designed
72 specifically for this case - it will grab the first returned result
73 without even instantiating a cursor.
75 Before replacing all your calls to C<first()> with C<single()> please observe the
82 While single() takes a search condition just like search() does, it does
83 _not_ accept search attributes. However one can always chain a single() to
86 my $top_cd = $cd_rs->search({}, { order_by => 'rating' })->single;
91 Since single() is the engine behind find(), it is designed to fetch a
92 single row per database query. Thus a warning will be issued when the
93 underlying SELECT returns more than one row. Sometimes however this usage
94 is valid: i.e. we have an arbitrary number of cd's but only one of them is
95 at the top of the charts at any given time. If you know what you are doing,
96 you can silence the warning by explicitly limiting the resultset size:
98 my $top_cd = $cd_rs->search ({}, { order_by => 'rating', rows => 1 })->single;
102 =head2 Arbitrary SQL through a custom ResultSource
104 Sometimes you have to run arbitrary SQL because your query is too complex
105 (e.g. it contains Unions, Sub-Selects, Stored Procedures, etc.) or has to
106 be optimized for your database in a special way, but you still want to
107 get the results as a L<DBIx::Class::ResultSet>.
109 This is accomplished by defining a
110 L<ResultSource::View|DBIx::Class::ResultSource::View> for your query,
111 almost like you would define a regular ResultSource.
113 package My::Schema::Result::UserFriendsComplex;
116 use base qw/DBIx::Class::Core/;
118 __PACKAGE__->table_class('DBIx::Class::ResultSource::View');
120 # ->table, ->add_columns, etc.
122 # do not attempt to deploy() this view
123 __PACKAGE__->result_source_instance->is_virtual(1);
125 __PACKAGE__->result_source_instance->view_definition(q[
126 SELECT u.* FROM user u
127 INNER JOIN user_friends f ON u.id = f.user_id
128 WHERE f.friend_user_id = ?
130 SELECT u.* FROM user u
131 INNER JOIN user_friends f ON u.id = f.friend_user_id
135 Next, you can execute your complex query using bind parameters like this:
137 my $friends = $schema->resultset( 'UserFriendsComplex' )->search( {},
139 bind => [ 12345, 12345 ]
143 ... and you'll get back a perfect L<DBIx::Class::ResultSet> (except, of course,
144 that you cannot modify the rows it contains, ie. cannot call L</update>,
145 L</delete>, ... on it).
147 Note that you cannot have bind parameters unless is_virtual is set to true.
153 If you're using the old deprecated C<< $rsrc_instance->name(\'( SELECT ...') >>
154 method for custom SQL execution, you are highly encouraged to update your code
155 to use a virtual view as above. If you do not want to change your code, and just
156 want to suppress the deprecation warning when you call
157 L<DBIx::Class::Schema/deploy>, add this line to your source definition, so that
158 C<deploy> will exclude this "table":
160 sub sqlt_deploy_hook { $_[1]->schema->drop_table ($_[1]) }
164 =head2 Using specific columns
166 When you only want specific columns from a table, you can use
167 C<columns> to specify which ones you need. This is useful to avoid
168 loading columns with large amounts of data that you aren't about to
171 my $rs = $schema->resultset('Artist')->search(
174 columns => [qw/ name /]
179 # SELECT artist.name FROM artist
181 This is a shortcut for C<select> and C<as>, see below. C<columns>
182 cannot be used together with C<select> and C<as>.
184 =head2 Using database functions or stored procedures
186 The combination of C<select> and C<as> can be used to return the result of a
187 database function or stored procedure as a column value. You use C<select> to
188 specify the source for your column value (e.g. a column name, function, or
189 stored procedure name). You then use C<as> to set the column name you will use
190 to access the returned value:
192 my $rs = $schema->resultset('Artist')->search(
195 select => [ 'name', { LENGTH => 'name' } ],
196 as => [qw/ name name_length /],
201 # SELECT name name, LENGTH( name )
204 Note that the C<as> attribute B<has absolutely nothing to do> with the sql
205 syntax C< SELECT foo AS bar > (see the documentation in
206 L<DBIx::Class::ResultSet/ATTRIBUTES>). You can control the C<AS> part of the
207 generated SQL via the C<-as> field attribute as follows:
209 my $rs = $schema->resultset('Artist')->search(
214 '+select' => [ { count => 'cds.cdid', -as => 'amount_of_cds' } ],
215 '+as' => [qw/num_cds/],
216 order_by => { -desc => 'amount_of_cds' },
221 # SELECT me.artistid, me.name, me.rank, me.charfield, COUNT( cds.cdid ) AS amount_of_cds
222 # FROM artist me LEFT JOIN cd cds ON cds.artist = me.artistid
223 # GROUP BY me.artistid, me.name, me.rank, me.charfield
224 # ORDER BY amount_of_cds DESC
227 If your alias exists as a column in your base class (i.e. it was added with
228 L<add_columns|DBIx::Class::ResultSource/add_columns>), you just access it as
229 normal. Our C<Artist> class has a C<name> column, so we just use the C<name>
232 my $artist = $rs->first();
233 my $name = $artist->name();
235 If on the other hand the alias does not correspond to an existing column, you
236 have to fetch the value using the C<get_column> accessor:
238 my $name_length = $artist->get_column('name_length');
240 If you don't like using C<get_column>, you can always create an accessor for
241 any of your aliases using either of these:
243 # Define accessor manually:
244 sub name_length { shift->get_column('name_length'); }
246 # Or use DBIx::Class::AccessorGroup:
247 __PACKAGE__->mk_group_accessors('column' => 'name_length');
249 See also L</Using SQL functions on the left hand side of a comparison>.
251 =head2 SELECT DISTINCT with multiple columns
253 my $rs = $schema->resultset('Artist')->search(
256 columns => [ qw/artist_id name rank/ ],
261 my $rs = $schema->resultset('Artist')->search(
264 columns => [ qw/artist_id name rank/ ],
265 group_by => [ qw/artist_id name rank/ ],
270 # SELECT me.artist_id, me.name, me.rank
272 # GROUP BY artist_id, name, rank
274 =head2 SELECT COUNT(DISTINCT colname)
276 my $rs = $schema->resultset('Artist')->search(
279 columns => [ qw/name/ ],
284 my $rs = $schema->resultset('Artist')->search(
287 columns => [ qw/name/ ],
288 group_by => [ qw/name/ ],
292 my $count = $rs->count;
295 # SELECT COUNT( * ) FROM (SELECT me.name FROM artist me GROUP BY me.name) count_subq:
297 =head2 Grouping results
299 L<DBIx::Class> supports C<GROUP BY> as follows:
301 my $rs = $schema->resultset('Artist')->search(
305 select => [ 'name', { count => 'cds.id' } ],
306 as => [qw/ name cd_count /],
307 group_by => [qw/ name /]
312 # SELECT name, COUNT( cd.id ) FROM artist
313 # LEFT JOIN cd ON artist.id = cd.artist
316 Please see L<DBIx::Class::ResultSet/ATTRIBUTES> documentation if you
317 are in any way unsure about the use of the attributes above (C< join
318 >, C< select >, C< as > and C< group_by >).
322 You can write subqueries relatively easily in DBIC.
324 my $inside_rs = $schema->resultset('Artist')->search({
325 name => [ 'Billy Joel', 'Brittany Spears' ],
328 my $rs = $schema->resultset('CD')->search({
329 artist_id => { 'IN' => $inside_rs->get_column('id')->as_query },
332 The usual operators ( =, !=, IN, NOT IN, etc) are supported.
334 B<NOTE>: You have to explicitly use '=' when doing an equality comparison.
335 The following will B<not> work:
337 my $rs = $schema->resultset('CD')->search({
338 artist_id => $inside_rs->get_column('id')->as_query, # does NOT work
343 Subqueries are supported in the where clause (first hashref), and in the
344 from, select, and +select attributes.
346 =head3 Correlated subqueries
348 my $cdrs = $schema->resultset('CD');
349 my $rs = $cdrs->search({
351 '=' => $cdrs->search(
352 { artist_id => { '=' => \'me.artist_id' } },
354 )->get_column('year')->max_rs->as_query,
358 That creates the following SQL:
360 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
363 SELECT MAX(inner.year)
365 WHERE artist_id = me.artist_id
368 =head2 Predefined searches
370 You can write your own L<DBIx::Class::ResultSet> class by inheriting from it
371 and defining often used searches as methods:
373 package My::DBIC::ResultSet::CD;
376 use base 'DBIx::Class::ResultSet';
378 sub search_cds_ordered {
381 return $self->search(
383 { order_by => 'name DESC' },
389 If you're using L<DBIx::Class::Schema/load_namespaces>, simply place the file
390 into the C<ResultSet> directory next to your C<Result> directory, and it will
391 be automatically loaded.
393 If however you are still using L<DBIx::Class::Schema/load_classes>, first tell
394 DBIx::Class to create an instance of the ResultSet class for you, in your
395 My::DBIC::Schema::CD class:
397 # class definition as normal
398 use base 'DBIx::Class::Core';
399 __PACKAGE__->table('cd');
401 # tell DBIC to use the custom ResultSet class
402 __PACKAGE__->resultset_class('My::DBIC::ResultSet::CD');
404 Note that C<resultset_class> must be called after C<load_components> and C<table>, or you will get errors about missing methods.
406 Then call your new method in your code:
408 my $ordered_cds = $schema->resultset('CD')->search_cds_ordered();
410 =head2 Using SQL functions on the left hand side of a comparison
412 Using SQL functions on the left hand side of a comparison is generally not a
413 good idea since it requires a scan of the entire table. (Unless your RDBMS
414 supports indexes on expressions - including return values of functions -, and
415 you create an index on the return value of the function in question.) However,
416 it can be accomplished with C<DBIx::Class> when necessary.
418 If you do not have quoting on, simply include the function in your search
419 specification as you would any column:
421 $rs->search({ 'YEAR(date_of_birth)' => 1979 });
423 With quoting on, or for a more portable solution, use literal SQL values with
426 $rs->search(\[ 'YEAR(date_of_birth) = ?', [ plain_value => 1979 ] ]);
429 # SELECT * FROM employee WHERE YEAR(date_of_birth) = ?
433 -nest => \[ 'YEAR(date_of_birth) = ?', [ plain_value => 1979 ] ],
437 # SELECT * FROM employee WHERE name = ? AND YEAR(date_of_birth) = ?
439 Note: the C<plain_value> string in the C<< [ plain_value => 1979 ] >> part
440 should be either the same as the name of the column (do this if the type of the
441 return value of the function is the same as the type of the column) or
442 otherwise it's essentially a dummy string currently (use C<plain_value> as a
443 habit). It is used by L<DBIx::Class> to handle special column types.
445 See also L<SQL::Abstract/Literal SQL with placeholders and bind values
448 =head1 JOINS AND PREFETCHING
450 =head2 Using joins and prefetch
452 You can use the C<join> attribute to allow searching on, or sorting your
453 results by, one or more columns in a related table.
455 This requires that you have defined the L<DBIx::Class::Relationship>. For example :
457 My::Schema::CD->has_many( artists => 'My::Schema::Artist', 'artist_id');
459 To return all CDs matching a particular artist name, you specify the name of the relationship ('artists'):
461 my $rs = $schema->resultset('CD')->search(
463 'artists.name' => 'Bob Marley'
466 join => 'artists', # join the artist table
471 # SELECT cd.* FROM cd
472 # JOIN artist ON cd.artist = artist.id
473 # WHERE artist.name = 'Bob Marley'
475 In that example both the join, and the condition use the relationship name rather than the table name
476 (see L<DBIx::Class::Manual::Joining> for more details on aliasing ).
478 If required, you can now sort on any column in the related tables by including
479 it in your C<order_by> attribute, (again using the aliased relation name rather than table name) :
481 my $rs = $schema->resultset('CD')->search(
483 'artists.name' => 'Bob Marley'
487 order_by => [qw/ artists.name /]
492 # SELECT cd.* FROM cd
493 # JOIN artist ON cd.artist = artist.id
494 # WHERE artist.name = 'Bob Marley'
495 # ORDER BY artist.name
497 Note that the C<join> attribute should only be used when you need to search or
498 sort using columns in a related table. Joining related tables when you only
499 need columns from the main table will make performance worse!
501 Now let's say you want to display a list of CDs, each with the name of the
502 artist. The following will work fine:
504 while (my $cd = $rs->next) {
505 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
508 There is a problem however. We have searched both the C<cd> and C<artist> tables
509 in our main query, but we have only returned data from the C<cd> table. To get
510 the artist name for any of the CD objects returned, L<DBIx::Class> will go back
513 SELECT artist.* FROM artist WHERE artist.id = ?
515 A statement like the one above will run for each and every CD returned by our
516 main query. Five CDs, five extra queries. A hundred CDs, one hundred extra
519 Thankfully, L<DBIx::Class> has a C<prefetch> attribute to solve this problem.
520 This allows you to fetch results from related tables in advance:
522 my $rs = $schema->resultset('CD')->search(
524 'artists.name' => 'Bob Marley'
528 order_by => [qw/ artists.name /],
529 prefetch => 'artists' # return artist data too!
533 # Equivalent SQL (note SELECT from both "cd" and "artist"):
534 # SELECT cd.*, artist.* FROM cd
535 # JOIN artist ON cd.artist = artist.id
536 # WHERE artist.name = 'Bob Marley'
537 # ORDER BY artist.name
539 The code to print the CD list remains the same:
541 while (my $cd = $rs->next) {
542 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
545 L<DBIx::Class> has now prefetched all matching data from the C<artist> table,
546 so no additional SQL statements are executed. You now have a much more
549 Also note that C<prefetch> should only be used when you know you will
550 definitely use data from a related table. Pre-fetching related tables when you
551 only need columns from the main table will make performance worse!
553 =head2 Multiple joins
555 In the examples above, the C<join> attribute was a scalar. If you
556 pass an array reference instead, you can join to multiple tables. In
557 this example, we want to limit the search further, using
560 # Relationships defined elsewhere:
561 # CD->belongs_to('artist' => 'Artist');
562 # CD->has_one('liner_notes' => 'LinerNotes', 'cd');
563 my $rs = $schema->resultset('CD')->search(
565 'artist.name' => 'Bob Marley'
566 'liner_notes.notes' => { 'like', '%some text%' },
569 join => [qw/ artist liner_notes /],
570 order_by => [qw/ artist.name /],
575 # SELECT cd.*, artist.*, liner_notes.* FROM cd
576 # JOIN artist ON cd.artist = artist.id
577 # JOIN liner_notes ON cd.id = liner_notes.cd
578 # WHERE artist.name = 'Bob Marley'
579 # ORDER BY artist.name
581 =head2 Multi-step joins
583 Sometimes you want to join more than one relationship deep. In this example,
584 we want to find all C<Artist> objects who have C<CD>s whose C<LinerNotes>
585 contain a specific string:
587 # Relationships defined elsewhere:
588 # Artist->has_many('cds' => 'CD', 'artist');
589 # CD->has_one('liner_notes' => 'LinerNotes', 'cd');
591 my $rs = $schema->resultset('Artist')->search(
593 'liner_notes.notes' => { 'like', '%some text%' },
597 'cds' => 'liner_notes'
603 # SELECT artist.* FROM artist
604 # LEFT JOIN cd ON artist.id = cd.artist
605 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
606 # WHERE liner_notes.notes LIKE '%some text%'
608 Joins can be nested to an arbitrary level. So if we decide later that we
609 want to reduce the number of Artists returned based on who wrote the liner
612 # Relationship defined elsewhere:
613 # LinerNotes->belongs_to('author' => 'Person');
615 my $rs = $schema->resultset('Artist')->search(
617 'liner_notes.notes' => { 'like', '%some text%' },
618 'author.name' => 'A. Writer'
623 'liner_notes' => 'author'
630 # SELECT artist.* FROM artist
631 # LEFT JOIN cd ON artist.id = cd.artist
632 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
633 # LEFT JOIN author ON author.id = liner_notes.author
634 # WHERE liner_notes.notes LIKE '%some text%'
635 # AND author.name = 'A. Writer'
637 =head2 Multi-step and multiple joins
639 With various combinations of array and hash references, you can join
640 tables in any combination you desire. For example, to join Artist to
641 CD and Concert, and join CD to LinerNotes:
643 # Relationships defined elsewhere:
644 # Artist->has_many('concerts' => 'Concert', 'artist');
646 my $rs = $schema->resultset('Artist')->search(
659 # SELECT artist.* FROM artist
660 # LEFT JOIN cd ON artist.id = cd.artist
661 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
662 # LEFT JOIN concert ON artist.id = concert.artist
664 =head2 Multi-step prefetch
666 C<prefetch> can be nested more than one relationship
667 deep using the same syntax as a multi-step join:
669 my $rs = $schema->resultset('Tag')->search(
679 # SELECT tag.*, cd.*, artist.* FROM tag
680 # JOIN cd ON tag.cd = cd.id
681 # JOIN artist ON cd.artist = artist.id
683 Now accessing our C<cd> and C<artist> relationships does not need additional
686 my $tag = $rs->first;
687 print $tag->cd->artist->name;
689 =head1 ROW-LEVEL OPERATIONS
691 =head2 Retrieving a row object's Schema
693 It is possible to get a Schema object from a row object like so:
695 my $schema = $cd->result_source->schema;
696 # use the schema as normal:
697 my $artist_rs = $schema->resultset('Artist');
699 This can be useful when you don't want to pass around a Schema object to every
702 =head2 Getting the value of the primary key for the last database insert
704 AKA getting last_insert_id
706 Thanks to the core component PK::Auto, this is straightforward:
708 my $foo = $rs->create(\%blah);
710 my $id = $foo->id; # foo->my_primary_key_field will also work.
712 If you are not using autoincrementing primary keys, this will probably
713 not work, but then you already know the value of the last primary key anyway.
715 =head2 Stringification
717 Employ the standard stringification technique by using the L<overload>
720 To make an object stringify itself as a single column, use something
721 like this (replace C<name> with the column/method of your choice):
723 use overload '""' => sub { shift->name}, fallback => 1;
725 For more complex stringification, you can use an anonymous subroutine:
727 use overload '""' => sub { $_[0]->name . ", " .
728 $_[0]->address }, fallback => 1;
730 =head3 Stringification Example
732 Suppose we have two tables: C<Product> and C<Category>. The table
735 Product(id, Description, category)
736 Category(id, Description)
738 C<category> is a foreign key into the Category table.
740 If you have a Product object C<$obj> and write something like
744 things will not work as expected.
746 To obtain, for example, the category description, you should add this
747 method to the class defining the Category table:
749 use overload "" => sub {
752 return $self->Description;
755 =head2 Want to know if find_or_create found or created a row?
757 Just use C<find_or_new> instead, then check C<in_storage>:
759 my $obj = $rs->find_or_new({ blah => 'blarg' });
760 unless ($obj->in_storage) {
762 # do whatever else you wanted if it was a new row
765 =head2 Static sub-classing DBIx::Class result classes
767 AKA adding additional relationships/methods/etc. to a model for a
768 specific usage of the (shared) model.
772 package My::App::Schema;
774 use base 'DBIx::Class::Schema';
776 # load subclassed classes from My::App::Schema::Result/ResultSet
777 __PACKAGE__->load_namespaces;
779 # load classes from shared model
781 'My::Shared::Model::Result' => [qw/
788 B<Result-Subclass definition>
790 package My::App::Schema::Result::Baz;
794 use base 'My::Shared::Model::Result::Baz';
796 # WARNING: Make sure you call table() again in your subclass,
797 # otherwise DBIx::Class::ResultSourceProxy::Table will not be called
798 # and the class name is not correctly registered as a source
799 __PACKAGE__->table('baz');
801 sub additional_method {
802 return "I'm an additional method only needed by this app";
807 =head2 Dynamic Sub-classing DBIx::Class proxy classes
809 AKA multi-class object inflation from one table
811 L<DBIx::Class> classes are proxy classes, therefore some different
812 techniques need to be employed for more than basic subclassing. In
813 this example we have a single user table that carries a boolean bit
814 for admin. We would like like to give the admin users
815 objects (L<DBIx::Class::Row>) the same methods as a regular user but
816 also special admin only methods. It doesn't make sense to create two
817 separate proxy-class files for this. We would be copying all the user
818 methods into the Admin class. There is a cleaner way to accomplish
821 Overriding the C<inflate_result> method within the User proxy-class
822 gives us the effect we want. This method is called by
823 L<DBIx::Class::ResultSet> when inflating a result from storage. So we
824 grab the object being returned, inspect the values we are looking for,
825 bless it if it's an admin object, and then return it. See the example
832 use base qw/DBIx::Class::Schema/;
834 __PACKAGE__->load_namespaces;
839 B<Proxy-Class definitions>
841 package My::Schema::Result::User;
845 use base qw/DBIx::Class::Core/;
847 ### Define what our admin class is, for ensure_class_loaded()
848 my $admin_class = __PACKAGE__ . '::Admin';
850 __PACKAGE__->table('users');
852 __PACKAGE__->add_columns(qw/user_id email password
853 firstname lastname active
856 __PACKAGE__->set_primary_key('user_id');
860 my $ret = $self->next::method(@_);
861 if( $ret->admin ) {### If this is an admin, rebless for extra functions
862 $self->ensure_class_loaded( $admin_class );
863 bless $ret, $admin_class;
869 print "I am a regular user.\n";
876 package My::Schema::Result::User::Admin;
880 use base qw/My::Schema::Result::User/;
882 # This line is important
883 __PACKAGE__->table('users');
887 print "I am an admin.\n";
893 print "I am doing admin stuff\n";
905 my $user_data = { email => 'someguy@place.com',
909 my $admin_data = { email => 'someadmin@adminplace.com',
913 my $schema = My::Schema->connection('dbi:Pg:dbname=test');
915 $schema->resultset('User')->create( $user_data );
916 $schema->resultset('User')->create( $admin_data );
918 ### Now we search for them
919 my $user = $schema->resultset('User')->single( $user_data );
920 my $admin = $schema->resultset('User')->single( $admin_data );
922 print ref $user, "\n";
923 print ref $admin, "\n";
925 print $user->password , "\n"; # pass1
926 print $admin->password , "\n";# pass2; inherited from User
927 print $user->hello , "\n";# I am a regular user.
928 print $admin->hello, "\n";# I am an admin.
930 ### The statement below will NOT print
931 print "I can do admin stuff\n" if $user->can('do_admin_stuff');
932 ### The statement below will print
933 print "I can do admin stuff\n" if $admin->can('do_admin_stuff');
935 Alternatively you can use L<DBIx::Class::DynamicSubclass> that implements
936 exactly the above functionality.
938 =head2 Skip row object creation for faster results
940 DBIx::Class is not built for speed, it's built for convenience and
941 ease of use, but sometimes you just need to get the data, and skip the
944 To do this simply use L<DBIx::Class::ResultClass::HashRefInflator>.
946 my $rs = $schema->resultset('CD');
948 $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
950 my $hash_ref = $rs->find(1);
954 Beware, changing the Result class using
955 L<DBIx::Class::ResultSet/result_class> will replace any existing class
956 completely including any special components loaded using
957 load_components, eg L<DBIx::Class::InflateColumn::DateTime>.
959 =head2 Get raw data for blindingly fast results
961 If the L<HashRefInflator|DBIx::Class::ResultClass::HashRefInflator> solution
962 above is not fast enough for you, you can use a DBIx::Class to return values
963 exactly as they come out of the database with none of the convenience methods
966 This is used like so:
968 my $cursor = $rs->cursor
969 while (my @vals = $cursor->next) {
970 # use $val[0..n] here
973 You will need to map the array offsets to particular columns (you can
974 use the L<DBIx::Class::ResultSet/select> attribute of L<DBIx::Class::ResultSet/search> to force ordering).
976 =head1 RESULTSET OPERATIONS
978 =head2 Getting Schema from a ResultSet
980 To get the L<DBIx::Class::Schema> object from a ResultSet, do the following:
982 $rs->result_source->schema
984 =head2 Getting Columns Of Data
988 If you want to find the sum of a particular column there are several
989 ways, the obvious one is to use search:
991 my $rs = $schema->resultset('Items')->search(
994 select => [ { sum => 'Cost' } ],
995 as => [ 'total_cost' ], # remember this 'as' is for DBIx::Class::ResultSet not SQL
998 my $tc = $rs->first->get_column('total_cost');
1000 Or, you can use the L<DBIx::Class::ResultSetColumn>, which gets
1001 returned when you ask the C<ResultSet> for a column using
1004 my $cost = $schema->resultset('Items')->get_column('Cost');
1005 my $tc = $cost->sum;
1007 With this you can also do:
1009 my $minvalue = $cost->min;
1010 my $maxvalue = $cost->max;
1012 Or just iterate through the values of this column only:
1014 while ( my $c = $cost->next ) {
1018 foreach my $c ($cost->all) {
1022 C<ResultSetColumn> only has a limited number of built-in functions. If
1023 you need one that it doesn't have, then you can use the C<func> method
1026 my $avg = $cost->func('AVERAGE');
1028 This will cause the following SQL statement to be run:
1030 SELECT AVERAGE(Cost) FROM Items me
1032 Which will of course only work if your database supports this function.
1033 See L<DBIx::Class::ResultSetColumn> for more documentation.
1035 =head2 Creating a result set from a set of rows
1037 Sometimes you have a (set of) row objects that you want to put into a
1038 resultset without the need to hit the DB again. You can do that by using the
1039 L<set_cache|DBIx::Class::Resultset/set_cache> method:
1041 my @uploadable_groups;
1042 while (my $group = $groups->next) {
1043 if ($group->can_upload($self)) {
1044 push @uploadable_groups, $group;
1047 my $new_rs = $self->result_source->resultset;
1048 $new_rs->set_cache(\@uploadable_groups);
1052 =head1 USING RELATIONSHIPS
1054 =head2 Create a new row in a related table
1056 my $author = $book->create_related('author', { name => 'Fred'});
1058 =head2 Search in a related table
1060 Only searches for books named 'Titanic' by the author in $author.
1062 my $books_rs = $author->search_related('books', { name => 'Titanic' });
1064 =head2 Delete data in a related table
1066 Deletes only the book named Titanic by the author in $author.
1068 $author->delete_related('books', { name => 'Titanic' });
1070 =head2 Ordering a relationship result set
1072 If you always want a relation to be ordered, you can specify this when you
1073 create the relationship.
1075 To order C<< $book->pages >> by descending page_number, create the relation
1078 __PACKAGE__->has_many('pages' => 'Page', 'book', { order_by => { -desc => 'page_number'} } );
1080 =head2 Filtering a relationship result set
1082 If you want to get a filtered result set, you can just add add to $attr as follows:
1084 __PACKAGE__->has_many('pages' => 'Page', 'book', { where => { scrap => 0 } } );
1086 =head2 Many-to-many relationships
1088 This is straightforward using L<ManyToMany|DBIx::Class::Relationship/many_to_many>:
1091 use base 'DBIx::Class::Core';
1092 __PACKAGE__->table('user');
1093 __PACKAGE__->add_columns(qw/id name/);
1094 __PACKAGE__->set_primary_key('id');
1095 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'user');
1096 __PACKAGE__->many_to_many('addresses' => 'user_address', 'address');
1098 package My::UserAddress;
1099 use base 'DBIx::Class::Core';
1100 __PACKAGE__->table('user_address');
1101 __PACKAGE__->add_columns(qw/user address/);
1102 __PACKAGE__->set_primary_key(qw/user address/);
1103 __PACKAGE__->belongs_to('user' => 'My::User');
1104 __PACKAGE__->belongs_to('address' => 'My::Address');
1106 package My::Address;
1107 use base 'DBIx::Class::Core';
1108 __PACKAGE__->table('address');
1109 __PACKAGE__->add_columns(qw/id street town area_code country/);
1110 __PACKAGE__->set_primary_key('id');
1111 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'address');
1112 __PACKAGE__->many_to_many('users' => 'user_address', 'user');
1114 $rs = $user->addresses(); # get all addresses for a user
1115 $rs = $address->users(); # get all users for an address
1117 my $address = $user->add_to_addresses( # returns a My::Address instance,
1118 # NOT a My::UserAddress instance!
1120 country => 'United Kingdom',
1127 =head2 Relationships across DB schemas
1129 Mapping relationships across L<DB schemas|DBIx::Class::Manual::Glossary/DB schema>
1130 is easy as long as the schemas themselves are all accessible via the same DBI
1131 connection. In most cases, this means that they are on the same database host
1132 as each other and your connecting database user has the proper permissions to them.
1134 To accomplish this one only needs to specify the DB schema name in the table
1135 declaration, like so...
1137 package MyDatabase::Main::Artist;
1138 use base qw/DBIx::Class::Core/;
1140 __PACKAGE__->table('database1.artist'); # will use "database1.artist" in FROM clause
1142 __PACKAGE__->add_columns(qw/ artist_id name /);
1143 __PACKAGE__->set_primary_key('artist_id');
1144 __PACKAGE__->has_many('cds' => 'MyDatabase::Main::Cd');
1148 Whatever string you specify there will be used to build the "FROM" clause in SQL
1151 The big drawback to this is you now have DB schema names hardcoded in your
1152 class files. This becomes especially troublesome if you have multiple instances
1153 of your application to support a change lifecycle (e.g. DEV, TEST, PROD) and
1154 the DB schemas are named based on the environment (e.g. database1_dev).
1156 However, one can dynamically "map" to the proper DB schema by overriding the
1157 L<connection|DBIx::Class::Schama/connection> method in your Schema class and
1158 building a renaming facility, like so:
1160 package MyDatabase::Schema;
1163 extends 'DBIx::Class::Schema';
1165 around connection => sub {
1166 my ( $inner, $self, $dsn, $username, $pass, $attr ) = ( shift, @_ );
1168 my $postfix = delete $attr->{schema_name_postfix};
1173 $self->append_db_name($postfix);
1177 sub append_db_name {
1178 my ( $self, $postfix ) = @_;
1182 { $_->name =~ /^\w+\./mx }
1184 { $self->source($_) }
1187 foreach my $source (@sources_with_db) {
1188 my $name = $source->name;
1189 $name =~ s{^(\w+)\.}{${1}${postfix}\.}mx;
1191 $source->name($name);
1197 By overridding the L<connection|DBIx::Class::Schama/connection>
1198 method and extracting a custom option from the provided \%attr hashref one can
1199 then simply iterate over all the Schema's ResultSources, renaming them as
1202 To use this facility, simply add or modify the \%attr hashref that is passed to
1203 L<connection|DBIx::Class::Schama/connect>, as follows:
1206 = MyDatabase::Schema->connect(
1211 schema_name_postfix => '_dev'
1212 # ... Other options as desired ...
1215 Obviously, one could accomplish even more advanced mapping via a hash map or a
1220 As of version 0.04001, there is improved transaction support in
1221 L<DBIx::Class::Storage> and L<DBIx::Class::Schema>. Here is an
1222 example of the recommended way to use it:
1224 my $genus = $schema->resultset('Genus')->find(12);
1226 my $coderef2 = sub {
1231 my $coderef1 = sub {
1232 $genus->add_to_species({ name => 'troglodyte' });
1235 $schema->txn_do($coderef2); # Can have a nested transaction. Only the outer will actualy commit
1236 return $genus->species;
1241 $rs = $schema->txn_do($coderef1);
1244 if ($@) { # Transaction failed
1245 die "the sky is falling!" #
1246 if ($@ =~ /Rollback failed/); # Rollback failed
1248 deal_with_failed_transaction();
1251 Nested transactions will work as expected. That is, only the outermost
1252 transaction will actually issue a commit to the $dbh, and a rollback
1253 at any level of any transaction will cause the entire nested
1254 transaction to fail.
1256 =head2 Nested transactions and auto-savepoints
1258 If savepoints are supported by your RDBMS, it is possible to achieve true
1259 nested transactions with minimal effort. To enable auto-savepoints via nested
1260 transactions, supply the C<< auto_savepoint = 1 >> connection attribute.
1262 Here is an example of true nested transactions. In the example, we start a big
1263 task which will create several rows. Generation of data for each row is a
1264 fragile operation and might fail. If we fail creating something, depending on
1265 the type of failure, we want to abort the whole task, or only skip the failed
1268 my $schema = MySchema->connect("dbi:Pg:dbname=my_db");
1270 # Start a transaction. Every database change from here on will only be
1271 # committed into the database if the eval block succeeds.
1273 $schema->txn_do(sub {
1276 my $job = $schema->resultset('Job')->create({ name=> 'big job' });
1277 # SQL: INSERT INTO job ( name) VALUES ( 'big job' );
1281 # Start a nested transaction, which in fact sets a savepoint.
1283 $schema->txn_do(sub {
1284 # SQL: SAVEPOINT savepoint_0;
1286 my $thing = $schema->resultset('Thing')->create({ job=>$job->id });
1287 # SQL: INSERT INTO thing ( job) VALUES ( 1 );
1290 # This will generate an error, thus setting $@
1292 $thing->update({force_fail=>'foo'});
1293 # SQL: UPDATE thing SET force_fail = 'foo'
1294 # WHERE ( id = 42 );
1299 # SQL: ROLLBACK TO SAVEPOINT savepoint_0;
1301 # There was an error while creating a $thing. Depending on the error
1302 # we want to abort the whole transaction, or only rollback the
1303 # changes related to the creation of this $thing
1305 # Abort the whole job
1306 if ($@ =~ /horrible_problem/) {
1307 print "something horrible happend, aborting job!";
1308 die $@; # rethrow error
1311 # Ignore this $thing, report the error, and continue with the
1313 print "Cannot create thing: $@";
1315 # There was no error, so save all changes since the last
1318 # SQL: RELEASE SAVEPOINT savepoint_0;
1323 # There was an error while handling the $job. Rollback all changes
1324 # since the transaction started, including the already committed
1325 # ('released') savepoints. There will be neither a new $job nor any
1326 # $thing entry in the database.
1330 print "ERROR: $@\n";
1333 # There was no error while handling the $job. Commit all changes.
1334 # Only now other connections can see the newly created $job and
1342 In this example it might be hard to see where the rollbacks, releases and
1343 commits are happening, but it works just the same as for plain L<<txn_do>>: If
1344 the C<eval>-block around C<txn_do> fails, a rollback is issued. If the C<eval>
1345 succeeds, the transaction is committed (or the savepoint released).
1347 While you can get more fine-grained controll using C<svp_begin>, C<svp_release>
1348 and C<svp_rollback>, it is strongly recommended to use C<txn_do> with coderefs.
1352 =head2 Creating Schemas From An Existing Database
1354 L<DBIx::Class::Schema::Loader> will connect to a database and create a
1355 L<DBIx::Class::Schema> and associated sources by examining the database.
1357 The recommend way of achieving this is to use the
1358 L<make_schema_at|DBIx::Class::Schema::Loader/make_schema_at> method:
1360 perl -MDBIx::Class::Schema::Loader=make_schema_at,dump_to_dir:./lib \
1361 -e 'make_schema_at("My::Schema", { debug => 1 }, [ "dbi:Pg:dbname=foo","postgres" ])'
1363 This will create a tree of files rooted at C<./lib/My/Schema/> containing
1364 source definitions for all the tables found in the C<foo> database.
1366 =head2 Creating DDL SQL
1368 The following functionality requires you to have L<SQL::Translator>
1369 (also known as "SQL Fairy") installed.
1371 To create a set of database-specific .sql files for the above schema:
1373 my $schema = My::Schema->connect($dsn);
1374 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
1379 By default this will create schema files in the current directory, for
1380 MySQL, SQLite and PostgreSQL, using the $VERSION from your Schema.pm.
1382 To create a new database using the schema:
1384 my $schema = My::Schema->connect($dsn);
1385 $schema->deploy({ add_drop_table => 1});
1387 To import created .sql files using the mysql client:
1389 mysql -h "host" -D "database" -u "user" -p < My_Schema_1.0_MySQL.sql
1391 To create C<ALTER TABLE> conversion scripts to update a database to a
1392 newer version of your schema at a later point, first set a new
1393 C<$VERSION> in your Schema file, then:
1395 my $schema = My::Schema->connect($dsn);
1396 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
1402 This will produce new database-specific .sql files for the new version
1403 of the schema, plus scripts to convert from version 0.1 to 0.2. This
1404 requires that the files for 0.1 as created above are available in the
1405 given directory to diff against.
1407 =head2 Select from dual
1409 Dummy tables are needed by some databases to allow calling functions
1410 or expressions that aren't based on table content, for examples of how
1411 this applies to various database types, see:
1412 L<http://troels.arvin.dk/db/rdbms/#other-dummy_table>.
1414 Note: If you're using Oracles dual table don't B<ever> do anything
1415 other than a select, if you CRUD on your dual table you *will* break
1418 Make a table class as you would for any other table
1420 package MyAppDB::Dual;
1423 use base 'DBIx::Class::Core';
1424 __PACKAGE__->table("Dual");
1425 __PACKAGE__->add_columns(
1427 { data_type => "VARCHAR2", is_nullable => 0, size => 1 },
1430 Once you've loaded your table class select from it using C<select>
1431 and C<as> instead of C<columns>
1433 my $rs = $schema->resultset('Dual')->search(undef,
1434 { select => [ 'sydate' ],
1439 All you have to do now is be careful how you access your resultset, the below
1440 will not work because there is no column called 'now' in the Dual table class
1442 while (my $dual = $rs->next) {
1443 print $dual->now."\n";
1445 # Can't locate object method "now" via package "MyAppDB::Dual" at headshot.pl line 23.
1447 You could of course use 'dummy' in C<as> instead of 'now', or C<add_columns> to
1448 your Dual class for whatever you wanted to select from dual, but that's just
1449 silly, instead use C<get_column>
1451 while (my $dual = $rs->next) {
1452 print $dual->get_column('now')."\n";
1457 my $cursor = $rs->cursor;
1458 while (my @vals = $cursor->next) {
1459 print $vals[0]."\n";
1462 In case you're going to use this "trick" together with L<DBIx::Class::Schema/deploy> or
1463 L<DBIx::Class::Schema/create_ddl_dir> a table called "dual" will be created in your
1464 current schema. This would overlap "sys.dual" and you could not fetch "sysdate" or
1465 "sequence.nextval" anymore from dual. To avoid this problem, just tell
1466 L<SQL::Translator> to not create table dual:
1469 add_drop_table => 1,
1470 parser_args => { sources => [ grep $_ ne 'Dual', schema->sources ] },
1472 $schema->create_ddl_dir( [qw/Oracle/], undef, './sql', undef, $sqlt_args );
1474 Or use L<DBIx::Class::ResultClass::HashRefInflator>
1476 $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
1477 while ( my $dual = $rs->next ) {
1478 print $dual->{now}."\n";
1481 Here are some example C<select> conditions to illustrate the different syntax
1482 you could use for doing stuff like
1483 C<oracles.heavily(nested(functions_can('take', 'lots'), OF), 'args')>
1485 # get a sequence value
1486 select => [ 'A_SEQ.nextval' ],
1488 # get create table sql
1489 select => [ { 'dbms_metadata.get_ddl' => [ "'TABLE'", "'ARTIST'" ]} ],
1491 # get a random num between 0 and 100
1492 select => [ { "trunc" => [ { "dbms_random.value" => [0,100] } ]} ],
1495 select => [ { 'extract' => [ \'year from sysdate' ] } ],
1498 select => [ {'round' => [{'cos' => [ \'180 * 3.14159265359/180' ]}]}],
1500 # which day of the week were you born on?
1501 select => [{'to_char' => [{'to_date' => [ "'25-DEC-1980'", "'dd-mon-yyyy'" ]}, "'day'"]}],
1503 # select 16 rows from dual
1504 select => [ "'hello'" ],
1506 group_by => [ 'cube( 1, 2, 3, 4 )' ],
1510 =head2 Adding Indexes And Functions To Your SQL
1512 Often you will want indexes on columns on your table to speed up searching. To
1513 do this, create a method called C<sqlt_deploy_hook> in the relevant source
1514 class (refer to the advanced
1515 L<callback system|DBIx::Class::ResultSource/sqlt_deploy_callback> if you wish
1516 to share a hook between multiple sources):
1518 package My::Schema::Result::Artist;
1520 __PACKAGE__->table('artist');
1521 __PACKAGE__->add_columns(id => { ... }, name => { ... })
1523 sub sqlt_deploy_hook {
1524 my ($self, $sqlt_table) = @_;
1526 $sqlt_table->add_index(name => 'idx_name', fields => ['name']);
1531 Sometimes you might want to change the index depending on the type of the
1532 database for which SQL is being generated:
1534 my ($db_type = $sqlt_table->schema->translator->producer_type)
1535 =~ s/^SQL::Translator::Producer:://;
1537 You can also add hooks to the schema level to stop certain tables being
1544 sub sqlt_deploy_hook {
1545 my ($self, $sqlt_schema) = @_;
1547 $sqlt_schema->drop_table('table_name');
1550 You could also add views, procedures or triggers to the output using
1551 L<SQL::Translator::Schema/add_view>,
1552 L<SQL::Translator::Schema/add_procedure> or
1553 L<SQL::Translator::Schema/add_trigger>.
1556 =head2 Schema versioning
1558 The following example shows simplistically how you might use DBIx::Class to
1559 deploy versioned schemas to your customers. The basic process is as follows:
1565 Create a DBIx::Class schema
1577 Modify schema to change functionality
1581 Deploy update to customers
1585 B<Create a DBIx::Class schema>
1587 This can either be done manually, or generated from an existing database as
1588 described under L</Creating Schemas From An Existing Database>
1592 Call L<DBIx::Class::Schema/create_ddl_dir> as above under L</Creating DDL SQL>.
1594 B<Deploy to customers>
1596 There are several ways you could deploy your schema. These are probably
1597 beyond the scope of this recipe, but might include:
1603 Require customer to apply manually using their RDBMS.
1607 Package along with your app, making database dump/schema update/tests
1608 all part of your install.
1612 B<Modify the schema to change functionality>
1614 As your application evolves, it may be necessary to modify your schema
1615 to change functionality. Once the changes are made to your schema in
1616 DBIx::Class, export the modified schema and the conversion scripts as
1617 in L</Creating DDL SQL>.
1619 B<Deploy update to customers>
1621 Add the L<DBIx::Class::Schema::Versioned> schema component to your
1622 Schema class. This will add a new table to your database called
1623 C<dbix_class_schema_vesion> which will keep track of which version is installed
1624 and warn if the user trys to run a newer schema version than the
1625 database thinks it has.
1627 Alternatively, you can send the conversion sql scripts to your
1630 =head2 Setting quoting for the generated SQL
1632 If the database contains column names with spaces and/or reserved words, they
1633 need to be quoted in the SQL queries. This is done using:
1635 $schema->storage->sql_maker->quote_char([ qw/[ ]/] );
1636 $schema->storage->sql_maker->name_sep('.');
1638 The first sets the quote characters. Either a pair of matching
1639 brackets, or a C<"> or C<'>:
1641 $schema->storage->sql_maker->quote_char('"');
1643 Check the documentation of your database for the correct quote
1644 characters to use. C<name_sep> needs to be set to allow the SQL
1645 generator to put the quotes the correct place.
1647 In most cases you should set these as part of the arguments passed to
1648 L<DBIx::Class::Schema/connect>:
1650 my $schema = My::Schema->connect(
1660 In some cases, quoting will be required for all users of a schema. To enforce
1661 this, you can also overload the C<connection> method for your schema class:
1665 my $rv = $self->next::method( @_ );
1666 $rv->storage->sql_maker->quote_char([ qw/[ ]/ ]);
1667 $rv->storage->sql_maker->name_sep('.');
1671 =head2 Setting limit dialect for SQL::Abstract::Limit
1673 In some cases, SQL::Abstract::Limit cannot determine the dialect of
1674 the remote SQL server by looking at the database handle. This is a
1675 common problem when using the DBD::JDBC, since the DBD-driver only
1676 know that in has a Java-driver available, not which JDBC driver the
1677 Java component has loaded. This specifically sets the limit_dialect
1678 to Microsoft SQL-server (See more names in SQL::Abstract::Limit
1681 __PACKAGE__->storage->sql_maker->limit_dialect('mssql');
1683 The JDBC bridge is one way of getting access to a MSSQL server from a platform
1684 that Microsoft doesn't deliver native client libraries for. (e.g. Linux)
1686 The limit dialect can also be set at connect time by specifying a
1687 C<limit_dialect> key in the final hash as shown above.
1689 =head2 Working with PostgreSQL array types
1691 You can also assign values to PostgreSQL array columns by passing array
1692 references in the C<\%columns> (C<\%vals>) hashref of the
1693 L<DBIx::Class::ResultSet/create> and L<DBIx::Class::Row/update> family of
1696 $resultset->create({
1697 numbers => [1, 2, 3]
1702 numbers => [1, 2, 3]
1709 In conditions (eg. C<\%cond> in the L<DBIx::Class::ResultSet/search> family of
1710 methods) you cannot directly use array references (since this is interpreted as
1711 a list of values to be C<OR>ed), but you can use the following syntax to force
1712 passing them as bind values:
1716 numbers => \[ '= ?', [numbers => [1, 2, 3]] ]
1720 See L<SQL::Abstract/array_datatypes> and L<SQL::Abstract/Literal SQL with
1721 placeholders and bind values (subqueries)> for more explanation. Note that
1722 L<DBIx::Class> sets L<SQL::Abstract/bindtype> to C<columns>, so you must pass
1723 the bind values (the C<[1, 2, 3]> arrayref in the above example) wrapped in
1724 arrayrefs together with the column name, like this: C<< [column_name => value]
1727 =head1 BOOTSTRAPPING/MIGRATING
1729 =head2 Easy migration from class-based to schema-based setup
1731 You want to start using the schema-based approach to L<DBIx::Class>
1732 (see L<SchemaIntro.pod>), but have an established class-based setup with lots
1733 of existing classes that you don't want to move by hand. Try this nifty script
1737 use SQL::Translator;
1739 my $schema = MyDB->schema_instance;
1741 my $translator = SQL::Translator->new(
1742 debug => $debug || 0,
1743 trace => $trace || 0,
1744 no_comments => $no_comments || 0,
1745 show_warnings => $show_warnings || 0,
1746 add_drop_table => $add_drop_table || 0,
1747 validate => $validate || 0,
1749 'DBIx::Schema' => $schema,
1752 'prefix' => 'My::Schema',
1756 $translator->parser('SQL::Translator::Parser::DBIx::Class');
1757 $translator->producer('SQL::Translator::Producer::DBIx::Class::File');
1759 my $output = $translator->translate(@args) or die
1760 "Error: " . $translator->error;
1764 You could use L<Module::Find> to search for all subclasses in the MyDB::*
1765 namespace, which is currently left as an exercise for the reader.
1767 =head1 OVERLOADING METHODS
1769 L<DBIx::Class> uses the L<Class::C3> package, which provides for redispatch of
1770 method calls, useful for things like default values and triggers. You have to
1771 use calls to C<next::method> to overload methods. More information on using
1772 L<Class::C3> with L<DBIx::Class> can be found in
1773 L<DBIx::Class::Manual::Component>.
1775 =head2 Setting default values for a row
1777 It's as simple as overriding the C<new> method. Note the use of
1781 my ( $class, $attrs ) = @_;
1783 $attrs->{foo} = 'bar' unless defined $attrs->{foo};
1785 my $new = $class->next::method($attrs);
1790 For more information about C<next::method>, look in the L<Class::C3>
1791 documentation. See also L<DBIx::Class::Manual::Component> for more
1792 ways to write your own base classes to do this.
1794 People looking for ways to do "triggers" with DBIx::Class are probably
1795 just looking for this.
1797 =head2 Changing one field whenever another changes
1799 For example, say that you have three columns, C<id>, C<number>, and
1800 C<squared>. You would like to make changes to C<number> and have
1801 C<squared> be automagically set to the value of C<number> squared.
1802 You can accomplish this by overriding C<store_column>:
1805 my ( $self, $name, $value ) = @_;
1806 if ($name eq 'number') {
1807 $self->squared($value * $value);
1809 $self->next::method($name, $value);
1812 Note that the hard work is done by the call to C<next::method>, which
1813 redispatches your call to store_column in the superclass(es).
1815 =head2 Automatically creating related objects
1817 You might have a class C<Artist> which has many C<CD>s. Further, you
1818 want to create a C<CD> object every time you insert an C<Artist> object.
1819 You can accomplish this by overriding C<insert> on your objects:
1822 my ( $self, @args ) = @_;
1823 $self->next::method(@args);
1824 $self->cds->new({})->fill_from_artist($self)->insert;
1828 where C<fill_from_artist> is a method you specify in C<CD> which sets
1829 values in C<CD> based on the data in the C<Artist> object you pass in.
1831 =head2 Wrapping/overloading a column accessor
1835 Say you have a table "Camera" and want to associate a description
1836 with each camera. For most cameras, you'll be able to generate the description from
1837 the other columns. However, in a few special cases you may want to associate a
1838 custom description with a camera.
1842 In your database schema, define a description field in the "Camera" table that
1843 can contain text and null values.
1845 In DBIC, we'll overload the column accessor to provide a sane default if no
1846 custom description is defined. The accessor will either return or generate the
1847 description, depending on whether the field is null or not.
1849 First, in your "Camera" schema class, define the description field as follows:
1851 __PACKAGE__->add_columns(description => { accessor => '_description' });
1853 Next, we'll define the accessor-wrapper subroutine:
1858 # If there is an update to the column, we'll let the original accessor
1860 return $self->_description(@_) if @_;
1862 # Fetch the column value.
1863 my $description = $self->_description;
1865 # If there's something in the description field, then just return that.
1866 return $description if defined $description && length $descripton;
1868 # Otherwise, generate a description.
1869 return $self->generate_description;
1872 =head1 DEBUGGING AND PROFILING
1874 =head2 DBIx::Class objects with Data::Dumper
1876 L<Data::Dumper> can be a very useful tool for debugging, but sometimes it can
1877 be hard to find the pertinent data in all the data it can generate.
1878 Specifically, if one naively tries to use it like so,
1882 my $cd = $schema->resultset('CD')->find(1);
1885 several pages worth of data from the CD object's schema and result source will
1886 be dumped to the screen. Since usually one is only interested in a few column
1887 values of the object, this is not very helpful.
1889 Luckily, it is possible to modify the data before L<Data::Dumper> outputs
1890 it. Simply define a hook that L<Data::Dumper> will call on the object before
1891 dumping it. For example,
1898 result_source => undef,
1906 local $Data::Dumper::Freezer = '_dumper_hook';
1908 my $cd = $schema->resultset('CD')->find(1);
1910 # dumps $cd without its ResultSource
1912 If the structure of your schema is such that there is a common base class for
1913 all your table classes, simply put a method similar to C<_dumper_hook> in the
1914 base class and set C<$Data::Dumper::Freezer> to its name and L<Data::Dumper>
1915 will automagically clean up your data before printing it. See
1916 L<Data::Dumper/EXAMPLES> for more information.
1920 When you enable L<DBIx::Class::Storage>'s debugging it prints the SQL
1921 executed as well as notifications of query completion and transaction
1922 begin/commit. If you'd like to profile the SQL you can subclass the
1923 L<DBIx::Class::Storage::Statistics> class and write your own profiling
1926 package My::Profiler;
1929 use base 'DBIx::Class::Storage::Statistics';
1931 use Time::HiRes qw(time);
1940 $self->print("Executing $sql: ".join(', ', @params)."\n");
1949 my $elapsed = sprintf("%0.4f", time() - $start);
1950 $self->print("Execution took $elapsed seconds.\n");
1956 You can then install that class as the debugging object:
1958 __PACKAGE__->storage->debugobj(new My::Profiler());
1959 __PACKAGE__->storage->debug(1);
1961 A more complicated example might involve storing each execution of SQL in an
1969 my $elapsed = time() - $start;
1970 push(@{ $calls{$sql} }, {
1976 You could then create average, high and low execution times for an SQL
1977 statement and dig down to see if certain parameters cause aberrant behavior.
1978 You might want to check out L<DBIx::Class::QueryLog> as well.
1980 =head1 STARTUP SPEED
1982 L<DBIx::Class|DBIx::Class> programs can have a significant startup delay
1983 as the ORM loads all the relevant classes. This section examines
1984 techniques for reducing the startup delay.
1986 These tips are are listed in order of decreasing effectiveness - so the
1987 first tip, if applicable, should have the greatest effect on your
1990 =head2 Statically Define Your Schema
1993 L<DBIx::Class::Schema::Loader|DBIx::Class::Schema::Loader> to build the
1994 classes dynamically based on the database schema then there will be a
1995 significant startup delay.
1997 For production use a statically defined schema (which can be generated
1998 using L<DBIx::Class::Schema::Loader|DBIx::Class::Schema::Loader> to dump
1999 the database schema once - see
2000 L<make_schema_at|DBIx::Class::Schema::Loader/make_schema_at> and
2001 L<dump_directory|DBIx::Class::Schema::Loader/dump_directory> for more
2002 details on creating static schemas from a database).
2004 =head2 Move Common Startup into a Base Class
2006 Typically L<DBIx::Class> result classes start off with
2008 use base qw/DBIx::Class::Core/;
2009 __PACKAGE__->load_components(qw/InflateColumn::DateTime/);
2011 If this preamble is moved into a common base class:-
2015 use base qw/DBIx::Class::Core/;
2016 __PACKAGE__->load_components(qw/InflateColumn::DateTime/);
2019 and each result class then uses this as a base:-
2021 use base qw/MyDBICbase/;
2023 then the load_components is only performed once, which can result in a
2024 considerable startup speedup for schemas with many classes.
2026 =head2 Explicitly List Schema Result Classes
2028 The schema class will normally contain
2030 __PACKAGE__->load_classes();
2032 to load the result classes. This will use L<Module::Find|Module::Find>
2033 to find and load the appropriate modules. Explicitly defining the
2034 classes you wish to load will remove the overhead of
2035 L<Module::Find|Module::Find> and the related directory operations:
2037 __PACKAGE__->load_classes(qw/ CD Artist Track /);
2039 If you are instead using the L<load_namespaces|DBIx::Class::Schema/load_namespaces>
2040 syntax to load the appropriate classes there is not a direct alternative
2041 avoiding L<Module::Find|Module::Find>.
2045 =head2 Cached statements
2047 L<DBIx::Class> normally caches all statements with L<< prepare_cached()|DBI/prepare_cached >>.
2048 This is normally a good idea, but if too many statements are cached, the database may use too much
2049 memory and may eventually run out and fail entirely. If you suspect this may be the case, you may want
2050 to examine DBI's L<< CachedKids|DBI/CachedKidsCachedKids_(hash_ref) >> hash:
2052 # print all currently cached prepared statements
2053 print for keys %{$schema->storage->dbh->{CachedKids}};
2054 # get a count of currently cached prepared statements
2055 my $count = scalar keys %{$schema->storage->dbh->{CachedKids}};
2057 If it's appropriate, you can simply clear these statements, automatically deallocating them in the
2060 my $kids = $schema->storage->dbh->{CachedKids};
2061 delete @{$kids}{keys %$kids} if scalar keys %$kids > 100;
2063 But what you probably want is to expire unused statements and not those that are used frequently.
2064 You can accomplish this with L<Tie::Cache> or L<Tie::Cache::LRU>:
2068 my $schema = DB::Main->connect($dbi_dsn, $user, $pass, {
2069 on_connect_do => sub { tie %{shift->_dbh->{CachedKids}}, 'Tie::Cache', 100 },