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, e.g. 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) me:
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 => { '=' => { -ident => '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 define frequently used searches as methods by subclassing
371 L<DBIx::Class::ResultSet>:
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 by resorting to
419 $rs->search(\[ 'YEAR(date_of_birth) = ?', [ plain_value => 1979 ] ]);
422 # SELECT * FROM employee WHERE YEAR(date_of_birth) = ?
424 $rs->search({ -and => [
426 \[ 'YEAR(date_of_birth) = ?', [ plain_value => 1979 ] ],
430 # SELECT * FROM employee WHERE name = ? AND YEAR(date_of_birth) = ?
432 Note: the C<plain_value> string in the C<< [ plain_value => 1979 ] >> part
433 should be either the same as the name of the column (do this if the type of the
434 return value of the function is the same as the type of the column) or in the
435 case of a function it's currently treated as a dummy string (it is a good idea
436 to use C<plain_value> or something similar to convey intent). The value is
437 currently only significant when handling special column types (BLOBs, arrays,
438 etc.), but this may change in the future.
440 See also L<SQL::Abstract/Literal SQL with placeholders and bind values
443 =head1 JOINS AND PREFETCHING
445 =head2 Using joins and prefetch
447 You can use the C<join> attribute to allow searching on, or sorting your
448 results by, one or more columns in a related table.
450 This requires that you have defined the L<DBIx::Class::Relationship>. For example :
452 My::Schema::CD->has_many( artists => 'My::Schema::Artist', 'artist_id');
454 To return all CDs matching a particular artist name, you specify the name of the relationship ('artists'):
456 my $rs = $schema->resultset('CD')->search(
458 'artists.name' => 'Bob Marley'
461 join => 'artists', # join the artist table
466 # SELECT cd.* FROM cd
467 # JOIN artist ON cd.artist = artist.id
468 # WHERE artist.name = 'Bob Marley'
470 In that example both the join, and the condition use the relationship name rather than the table name
471 (see L<DBIx::Class::Manual::Joining> for more details on aliasing ).
473 If required, you can now sort on any column in the related tables by including
474 it in your C<order_by> attribute, (again using the aliased relation name rather than table name) :
476 my $rs = $schema->resultset('CD')->search(
478 'artists.name' => 'Bob Marley'
482 order_by => [qw/ artists.name /]
487 # SELECT cd.* FROM cd
488 # JOIN artist ON cd.artist = artist.id
489 # WHERE artist.name = 'Bob Marley'
490 # ORDER BY artist.name
492 Note that the C<join> attribute should only be used when you need to search or
493 sort using columns in a related table. Joining related tables when you only
494 need columns from the main table will make performance worse!
496 Now let's say you want to display a list of CDs, each with the name of the
497 artist. The following will work fine:
499 while (my $cd = $rs->next) {
500 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
503 There is a problem however. We have searched both the C<cd> and C<artist> tables
504 in our main query, but we have only returned data from the C<cd> table. To get
505 the artist name for any of the CD objects returned, L<DBIx::Class> will go back
508 SELECT artist.* FROM artist WHERE artist.id = ?
510 A statement like the one above will run for each and every CD returned by our
511 main query. Five CDs, five extra queries. A hundred CDs, one hundred extra
514 Thankfully, L<DBIx::Class> has a C<prefetch> attribute to solve this problem.
515 This allows you to fetch results from related tables in advance:
517 my $rs = $schema->resultset('CD')->search(
519 'artists.name' => 'Bob Marley'
523 order_by => [qw/ artists.name /],
524 prefetch => 'artists' # return artist data too!
528 # Equivalent SQL (note SELECT from both "cd" and "artist"):
529 # SELECT cd.*, artist.* FROM cd
530 # JOIN artist ON cd.artist = artist.id
531 # WHERE artist.name = 'Bob Marley'
532 # ORDER BY artist.name
534 The code to print the CD list remains the same:
536 while (my $cd = $rs->next) {
537 print "CD: " . $cd->title . ", Artist: " . $cd->artist->name;
540 L<DBIx::Class> has now prefetched all matching data from the C<artist> table,
541 so no additional SQL statements are executed. You now have a much more
544 Also note that C<prefetch> should only be used when you know you will
545 definitely use data from a related table. Pre-fetching related tables when you
546 only need columns from the main table will make performance worse!
548 =head2 Multiple joins
550 In the examples above, the C<join> attribute was a scalar. If you
551 pass an array reference instead, you can join to multiple tables. In
552 this example, we want to limit the search further, using
555 # Relationships defined elsewhere:
556 # CD->belongs_to('artist' => 'Artist');
557 # CD->has_one('liner_notes' => 'LinerNotes', 'cd');
558 my $rs = $schema->resultset('CD')->search(
560 'artist.name' => 'Bob Marley'
561 'liner_notes.notes' => { 'like', '%some text%' },
564 join => [qw/ artist liner_notes /],
565 order_by => [qw/ artist.name /],
570 # SELECT cd.*, artist.*, liner_notes.* FROM cd
571 # JOIN artist ON cd.artist = artist.id
572 # JOIN liner_notes ON cd.id = liner_notes.cd
573 # WHERE artist.name = 'Bob Marley'
574 # ORDER BY artist.name
576 =head2 Multi-step joins
578 Sometimes you want to join more than one relationship deep. In this example,
579 we want to find all C<Artist> objects who have C<CD>s whose C<LinerNotes>
580 contain a specific string:
582 # Relationships defined elsewhere:
583 # Artist->has_many('cds' => 'CD', 'artist');
584 # CD->has_one('liner_notes' => 'LinerNotes', 'cd');
586 my $rs = $schema->resultset('Artist')->search(
588 'liner_notes.notes' => { 'like', '%some text%' },
592 'cds' => 'liner_notes'
598 # SELECT artist.* FROM artist
599 # LEFT JOIN cd ON artist.id = cd.artist
600 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
601 # WHERE liner_notes.notes LIKE '%some text%'
603 Joins can be nested to an arbitrary level. So if we decide later that we
604 want to reduce the number of Artists returned based on who wrote the liner
607 # Relationship defined elsewhere:
608 # LinerNotes->belongs_to('author' => 'Person');
610 my $rs = $schema->resultset('Artist')->search(
612 'liner_notes.notes' => { 'like', '%some text%' },
613 'author.name' => 'A. Writer'
618 'liner_notes' => 'author'
625 # SELECT artist.* FROM artist
626 # LEFT JOIN cd ON artist.id = cd.artist
627 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
628 # LEFT JOIN author ON author.id = liner_notes.author
629 # WHERE liner_notes.notes LIKE '%some text%'
630 # AND author.name = 'A. Writer'
632 =head2 Multi-step and multiple joins
634 With various combinations of array and hash references, you can join
635 tables in any combination you desire. For example, to join Artist to
636 CD and Concert, and join CD to LinerNotes:
638 # Relationships defined elsewhere:
639 # Artist->has_many('concerts' => 'Concert', 'artist');
641 my $rs = $schema->resultset('Artist')->search(
654 # SELECT artist.* FROM artist
655 # LEFT JOIN cd ON artist.id = cd.artist
656 # LEFT JOIN liner_notes ON cd.id = liner_notes.cd
657 # LEFT JOIN concert ON artist.id = concert.artist
659 =head2 Multi-step prefetch
661 C<prefetch> can be nested more than one relationship
662 deep using the same syntax as a multi-step join:
664 my $rs = $schema->resultset('Tag')->search(
674 # SELECT tag.*, cd.*, artist.* FROM tag
675 # JOIN cd ON tag.cd = cd.id
676 # JOIN artist ON cd.artist = artist.id
678 Now accessing our C<cd> and C<artist> relationships does not need additional
681 my $tag = $rs->first;
682 print $tag->cd->artist->name;
684 =head1 ROW-LEVEL OPERATIONS
686 =head2 Retrieving a row object's Schema
688 It is possible to get a Schema object from a row object like so:
690 my $schema = $cd->result_source->schema;
691 # use the schema as normal:
692 my $artist_rs = $schema->resultset('Artist');
694 This can be useful when you don't want to pass around a Schema object to every
697 =head2 Getting the value of the primary key for the last database insert
699 AKA getting last_insert_id
701 Thanks to the core component PK::Auto, this is straightforward:
703 my $foo = $rs->create(\%blah);
705 my $id = $foo->id; # foo->my_primary_key_field will also work.
707 If you are not using autoincrementing primary keys, this will probably
708 not work, but then you already know the value of the last primary key anyway.
710 =head2 Stringification
712 Employ the standard stringification technique by using the L<overload>
715 To make an object stringify itself as a single column, use something
716 like this (replace C<name> with the column/method of your choice):
718 use overload '""' => sub { shift->name}, fallback => 1;
720 For more complex stringification, you can use an anonymous subroutine:
722 use overload '""' => sub { $_[0]->name . ", " .
723 $_[0]->address }, fallback => 1;
725 =head3 Stringification Example
727 Suppose we have two tables: C<Product> and C<Category>. The table
730 Product(id, Description, category)
731 Category(id, Description)
733 C<category> is a foreign key into the Category table.
735 If you have a Product object C<$obj> and write something like
739 things will not work as expected.
741 To obtain, for example, the category description, you should add this
742 method to the class defining the Category table:
744 use overload "" => sub {
747 return $self->Description;
750 =head2 Want to know if find_or_create found or created a row?
752 Just use C<find_or_new> instead, then check C<in_storage>:
754 my $obj = $rs->find_or_new({ blah => 'blarg' });
755 unless ($obj->in_storage) {
757 # do whatever else you wanted if it was a new row
760 =head2 Static sub-classing DBIx::Class result classes
762 AKA adding additional relationships/methods/etc. to a model for a
763 specific usage of the (shared) model.
767 package My::App::Schema;
769 use base 'DBIx::Class::Schema';
771 # load subclassed classes from My::App::Schema::Result/ResultSet
772 __PACKAGE__->load_namespaces;
774 # load classes from shared model
776 'My::Shared::Model::Result' => [qw/
783 B<Result-Subclass definition>
785 package My::App::Schema::Result::Baz;
789 use base 'My::Shared::Model::Result::Baz';
791 # WARNING: Make sure you call table() again in your subclass,
792 # otherwise DBIx::Class::ResultSourceProxy::Table will not be called
793 # and the class name is not correctly registered as a source
794 __PACKAGE__->table('baz');
796 sub additional_method {
797 return "I'm an additional method only needed by this app";
802 =head2 Dynamic Sub-classing DBIx::Class proxy classes
804 AKA multi-class object inflation from one table
806 L<DBIx::Class> classes are proxy classes, therefore some different
807 techniques need to be employed for more than basic subclassing. In
808 this example we have a single user table that carries a boolean bit
809 for admin. We would like like to give the admin users
810 objects (L<DBIx::Class::Row>) the same methods as a regular user but
811 also special admin only methods. It doesn't make sense to create two
812 separate proxy-class files for this. We would be copying all the user
813 methods into the Admin class. There is a cleaner way to accomplish
816 Overriding the C<inflate_result> method within the User proxy-class
817 gives us the effect we want. This method is called by
818 L<DBIx::Class::ResultSet> when inflating a result from storage. So we
819 grab the object being returned, inspect the values we are looking for,
820 bless it if it's an admin object, and then return it. See the example
827 use base qw/DBIx::Class::Schema/;
829 __PACKAGE__->load_namespaces;
834 B<Proxy-Class definitions>
836 package My::Schema::Result::User;
840 use base qw/DBIx::Class::Core/;
842 ### Define what our admin class is, for ensure_class_loaded()
843 my $admin_class = __PACKAGE__ . '::Admin';
845 __PACKAGE__->table('users');
847 __PACKAGE__->add_columns(qw/user_id email password
848 firstname lastname active
851 __PACKAGE__->set_primary_key('user_id');
855 my $ret = $self->next::method(@_);
856 if( $ret->admin ) {### If this is an admin, rebless for extra functions
857 $self->ensure_class_loaded( $admin_class );
858 bless $ret, $admin_class;
864 print "I am a regular user.\n";
871 package My::Schema::Result::User::Admin;
875 use base qw/My::Schema::Result::User/;
877 # This line is important
878 __PACKAGE__->table('users');
882 print "I am an admin.\n";
888 print "I am doing admin stuff\n";
900 my $user_data = { email => 'someguy@place.com',
904 my $admin_data = { email => 'someadmin@adminplace.com',
908 my $schema = My::Schema->connection('dbi:Pg:dbname=test');
910 $schema->resultset('User')->create( $user_data );
911 $schema->resultset('User')->create( $admin_data );
913 ### Now we search for them
914 my $user = $schema->resultset('User')->single( $user_data );
915 my $admin = $schema->resultset('User')->single( $admin_data );
917 print ref $user, "\n";
918 print ref $admin, "\n";
920 print $user->password , "\n"; # pass1
921 print $admin->password , "\n";# pass2; inherited from User
922 print $user->hello , "\n";# I am a regular user.
923 print $admin->hello, "\n";# I am an admin.
925 ### The statement below will NOT print
926 print "I can do admin stuff\n" if $user->can('do_admin_stuff');
927 ### The statement below will print
928 print "I can do admin stuff\n" if $admin->can('do_admin_stuff');
930 Alternatively you can use L<DBIx::Class::DynamicSubclass> that implements
931 exactly the above functionality.
933 =head2 Skip row object creation for faster results
935 DBIx::Class is not built for speed, it's built for convenience and
936 ease of use, but sometimes you just need to get the data, and skip the
939 To do this simply use L<DBIx::Class::ResultClass::HashRefInflator>.
941 my $rs = $schema->resultset('CD');
943 $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
945 my $hash_ref = $rs->find(1);
949 Beware, changing the Result class using
950 L<DBIx::Class::ResultSet/result_class> will replace any existing class
951 completely including any special components loaded using
952 load_components, eg L<DBIx::Class::InflateColumn::DateTime>.
954 =head2 Get raw data for blindingly fast results
956 If the L<HashRefInflator|DBIx::Class::ResultClass::HashRefInflator> solution
957 above is not fast enough for you, you can use a DBIx::Class to return values
958 exactly as they come out of the database with none of the convenience methods
961 This is used like so:
963 my $cursor = $rs->cursor
964 while (my @vals = $cursor->next) {
965 # use $val[0..n] here
968 You will need to map the array offsets to particular columns (you can
969 use the L<DBIx::Class::ResultSet/select> attribute of L<DBIx::Class::ResultSet/search> to force ordering).
971 =head1 RESULTSET OPERATIONS
973 =head2 Getting Schema from a ResultSet
975 To get the L<DBIx::Class::Schema> object from a ResultSet, do the following:
977 $rs->result_source->schema
979 =head2 Getting Columns Of Data
983 If you want to find the sum of a particular column there are several
984 ways, the obvious one is to use search:
986 my $rs = $schema->resultset('Items')->search(
989 select => [ { sum => 'Cost' } ],
990 as => [ 'total_cost' ], # remember this 'as' is for DBIx::Class::ResultSet not SQL
993 my $tc = $rs->first->get_column('total_cost');
995 Or, you can use the L<DBIx::Class::ResultSetColumn>, which gets
996 returned when you ask the C<ResultSet> for a column using
999 my $cost = $schema->resultset('Items')->get_column('Cost');
1000 my $tc = $cost->sum;
1002 With this you can also do:
1004 my $minvalue = $cost->min;
1005 my $maxvalue = $cost->max;
1007 Or just iterate through the values of this column only:
1009 while ( my $c = $cost->next ) {
1013 foreach my $c ($cost->all) {
1017 C<ResultSetColumn> only has a limited number of built-in functions. If
1018 you need one that it doesn't have, then you can use the C<func> method
1021 my $avg = $cost->func('AVERAGE');
1023 This will cause the following SQL statement to be run:
1025 SELECT AVERAGE(Cost) FROM Items me
1027 Which will of course only work if your database supports this function.
1028 See L<DBIx::Class::ResultSetColumn> for more documentation.
1030 =head2 Creating a result set from a set of rows
1032 Sometimes you have a (set of) row objects that you want to put into a
1033 resultset without the need to hit the DB again. You can do that by using the
1034 L<set_cache|DBIx::Class::Resultset/set_cache> method:
1036 my @uploadable_groups;
1037 while (my $group = $groups->next) {
1038 if ($group->can_upload($self)) {
1039 push @uploadable_groups, $group;
1042 my $new_rs = $self->result_source->resultset;
1043 $new_rs->set_cache(\@uploadable_groups);
1047 =head1 USING RELATIONSHIPS
1049 =head2 Create a new row in a related table
1051 my $author = $book->create_related('author', { name => 'Fred'});
1053 =head2 Search in a related table
1055 Only searches for books named 'Titanic' by the author in $author.
1057 my $books_rs = $author->search_related('books', { name => 'Titanic' });
1059 =head2 Delete data in a related table
1061 Deletes only the book named Titanic by the author in $author.
1063 $author->delete_related('books', { name => 'Titanic' });
1065 =head2 Ordering a relationship result set
1067 If you always want a relation to be ordered, you can specify this when you
1068 create the relationship.
1070 To order C<< $book->pages >> by descending page_number, create the relation
1073 __PACKAGE__->has_many('pages' => 'Page', 'book', { order_by => { -desc => 'page_number'} } );
1075 =head2 Filtering a relationship result set
1077 If you want to get a filtered result set, you can just add add to $attr as follows:
1079 __PACKAGE__->has_many('pages' => 'Page', 'book', { where => { scrap => 0 } } );
1081 =head2 Many-to-many relationships
1083 This is straightforward using L<ManyToMany|DBIx::Class::Relationship/many_to_many>:
1086 use base 'DBIx::Class::Core';
1087 __PACKAGE__->table('user');
1088 __PACKAGE__->add_columns(qw/id name/);
1089 __PACKAGE__->set_primary_key('id');
1090 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'user');
1091 __PACKAGE__->many_to_many('addresses' => 'user_address', 'address');
1093 package My::UserAddress;
1094 use base 'DBIx::Class::Core';
1095 __PACKAGE__->table('user_address');
1096 __PACKAGE__->add_columns(qw/user address/);
1097 __PACKAGE__->set_primary_key(qw/user address/);
1098 __PACKAGE__->belongs_to('user' => 'My::User');
1099 __PACKAGE__->belongs_to('address' => 'My::Address');
1101 package My::Address;
1102 use base 'DBIx::Class::Core';
1103 __PACKAGE__->table('address');
1104 __PACKAGE__->add_columns(qw/id street town area_code country/);
1105 __PACKAGE__->set_primary_key('id');
1106 __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'address');
1107 __PACKAGE__->many_to_many('users' => 'user_address', 'user');
1109 $rs = $user->addresses(); # get all addresses for a user
1110 $rs = $address->users(); # get all users for an address
1112 my $address = $user->add_to_addresses( # returns a My::Address instance,
1113 # NOT a My::UserAddress instance!
1115 country => 'United Kingdom',
1122 =head2 Relationships across DB schemas
1124 Mapping relationships across L<DB schemas|DBIx::Class::Manual::Glossary/DB schema>
1125 is easy as long as the schemas themselves are all accessible via the same DBI
1126 connection. In most cases, this means that they are on the same database host
1127 as each other and your connecting database user has the proper permissions to them.
1129 To accomplish this one only needs to specify the DB schema name in the table
1130 declaration, like so...
1132 package MyDatabase::Main::Artist;
1133 use base qw/DBIx::Class::Core/;
1135 __PACKAGE__->table('database1.artist'); # will use "database1.artist" in FROM clause
1137 __PACKAGE__->add_columns(qw/ artist_id name /);
1138 __PACKAGE__->set_primary_key('artist_id');
1139 __PACKAGE__->has_many('cds' => 'MyDatabase::Main::Cd');
1143 Whatever string you specify there will be used to build the "FROM" clause in SQL
1146 The big drawback to this is you now have DB schema names hardcoded in your
1147 class files. This becomes especially troublesome if you have multiple instances
1148 of your application to support a change lifecycle (e.g. DEV, TEST, PROD) and
1149 the DB schemas are named based on the environment (e.g. database1_dev).
1151 However, one can dynamically "map" to the proper DB schema by overriding the
1152 L<connection|DBIx::Class::Schama/connection> method in your Schema class and
1153 building a renaming facility, like so:
1155 package MyDatabase::Schema;
1158 extends 'DBIx::Class::Schema';
1160 around connection => sub {
1161 my ( $inner, $self, $dsn, $username, $pass, $attr ) = ( shift, @_ );
1163 my $postfix = delete $attr->{schema_name_postfix};
1168 $self->append_db_name($postfix);
1172 sub append_db_name {
1173 my ( $self, $postfix ) = @_;
1177 { $_->name =~ /^\w+\./mx }
1179 { $self->source($_) }
1182 foreach my $source (@sources_with_db) {
1183 my $name = $source->name;
1184 $name =~ s{^(\w+)\.}{${1}${postfix}\.}mx;
1186 $source->name($name);
1192 By overridding the L<connection|DBIx::Class::Schama/connection>
1193 method and extracting a custom option from the provided \%attr hashref one can
1194 then simply iterate over all the Schema's ResultSources, renaming them as
1197 To use this facility, simply add or modify the \%attr hashref that is passed to
1198 L<connection|DBIx::Class::Schama/connect>, as follows:
1201 = MyDatabase::Schema->connect(
1206 schema_name_postfix => '_dev'
1207 # ... Other options as desired ...
1210 Obviously, one could accomplish even more advanced mapping via a hash map or a
1215 =head2 Transactions with txn_do
1217 As of version 0.04001, there is improved transaction support in
1218 L<DBIx::Class::Storage> and L<DBIx::Class::Schema>. Here is an
1219 example of the recommended way to use it:
1221 my $genus = $schema->resultset('Genus')->find(12);
1223 my $coderef2 = sub {
1228 my $coderef1 = sub {
1229 $genus->add_to_species({ name => 'troglodyte' });
1232 $schema->txn_do($coderef2); # Can have a nested transaction. Only the outer will actualy commit
1233 return $genus->species;
1239 $rs = $schema->txn_do($coderef1);
1241 # Transaction failed
1242 die "the sky is falling!" #
1243 if ($_ =~ /Rollback failed/); # Rollback failed
1245 deal_with_failed_transaction();
1248 Note: by default C<txn_do> will re-run the coderef one more time if an
1249 error occurs due to client disconnection (e.g. the server is bounced).
1250 You need to make sure that your coderef can be invoked multiple times
1251 without terrible side effects.
1253 Nested transactions will work as expected. That is, only the outermost
1254 transaction will actually issue a commit to the $dbh, and a rollback
1255 at any level of any transaction will cause the entire nested
1256 transaction to fail.
1258 =head2 Nested transactions and auto-savepoints
1260 If savepoints are supported by your RDBMS, it is possible to achieve true
1261 nested transactions with minimal effort. To enable auto-savepoints via nested
1262 transactions, supply the C<< auto_savepoint = 1 >> connection attribute.
1264 Here is an example of true nested transactions. In the example, we start a big
1265 task which will create several rows. Generation of data for each row is a
1266 fragile operation and might fail. If we fail creating something, depending on
1267 the type of failure, we want to abort the whole task, or only skip the failed
1270 my $schema = MySchema->connect("dbi:Pg:dbname=my_db");
1272 # Start a transaction. Every database change from here on will only be
1273 # committed into the database if the try block succeeds.
1277 $schema->txn_do(sub {
1280 my $job = $schema->resultset('Job')->create({ name=> 'big job' });
1281 # SQL: INSERT INTO job ( name) VALUES ( 'big job' );
1285 # Start a nested transaction, which in fact sets a savepoint.
1287 $schema->txn_do(sub {
1288 # SQL: SAVEPOINT savepoint_0;
1290 my $thing = $schema->resultset('Thing')->create({ job=>$job->id });
1291 # SQL: INSERT INTO thing ( job) VALUES ( 1 );
1294 # This will generate an error, thus setting $@
1296 $thing->update({force_fail=>'foo'});
1297 # SQL: UPDATE thing SET force_fail = 'foo'
1298 # WHERE ( id = 42 );
1302 # SQL: ROLLBACK TO SAVEPOINT savepoint_0;
1304 # There was an error while creating a $thing. Depending on the error
1305 # we want to abort the whole transaction, or only rollback the
1306 # changes related to the creation of this $thing
1308 # Abort the whole job
1309 if ($_ =~ /horrible_problem/) {
1310 print "something horrible happend, aborting job!";
1311 die $_; # rethrow error
1314 # Ignore this $thing, report the error, and continue with the
1316 print "Cannot create thing: $_";
1318 # There was no error, so save all changes since the last
1321 # SQL: RELEASE SAVEPOINT savepoint_0;
1329 # There was an error while handling the $job. Rollback all changes
1330 # since the transaction started, including the already committed
1331 # ('released') savepoints. There will be neither a new $job nor any
1332 # $thing entry in the database.
1336 print "ERROR: $exception\n";
1339 # There was no error while handling the $job. Commit all changes.
1340 # Only now other connections can see the newly created $job and
1348 In this example it might be hard to see where the rollbacks, releases and
1349 commits are happening, but it works just the same as for plain L<<txn_do>>: If
1350 the C<try>-block around C<txn_do> fails, a rollback is issued. If the C<try>
1351 succeeds, the transaction is committed (or the savepoint released).
1353 While you can get more fine-grained control using C<svp_begin>, C<svp_release>
1354 and C<svp_rollback>, it is strongly recommended to use C<txn_do> with coderefs.
1356 =head2 Simple Transactions with DBIx::Class::Storage::TxnScopeGuard
1358 An easy way to use transactions is with
1359 L<DBIx::Class::Storage::TxnScopeGuard>. See L</Automatically creating
1360 related objects> for an example.
1362 Note that unlike txn_do, TxnScopeGuard will only make sure the connection is
1363 alive when issuing the C<BEGIN> statement. It will not (and really can not)
1364 retry if the server goes away mid-operations, unlike C<txn_do>.
1368 =head2 Creating Schemas From An Existing Database
1370 L<DBIx::Class::Schema::Loader> will connect to a database and create a
1371 L<DBIx::Class::Schema> and associated sources by examining the database.
1373 The recommend way of achieving this is to use the
1374 L<make_schema_at|DBIx::Class::Schema::Loader/make_schema_at> method:
1376 perl -MDBIx::Class::Schema::Loader=make_schema_at,dump_to_dir:./lib \
1377 -e 'make_schema_at("My::Schema", { debug => 1 }, [ "dbi:Pg:dbname=foo","postgres" ])'
1379 This will create a tree of files rooted at C<./lib/My/Schema/> containing
1380 source definitions for all the tables found in the C<foo> database.
1382 =head2 Creating DDL SQL
1384 The following functionality requires you to have L<SQL::Translator>
1385 (also known as "SQL Fairy") installed.
1387 To create a set of database-specific .sql files for the above schema:
1389 my $schema = My::Schema->connect($dsn);
1390 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
1395 By default this will create schema files in the current directory, for
1396 MySQL, SQLite and PostgreSQL, using the $VERSION from your Schema.pm.
1398 To create a new database using the schema:
1400 my $schema = My::Schema->connect($dsn);
1401 $schema->deploy({ add_drop_table => 1});
1403 To import created .sql files using the mysql client:
1405 mysql -h "host" -D "database" -u "user" -p < My_Schema_1.0_MySQL.sql
1407 To create C<ALTER TABLE> conversion scripts to update a database to a
1408 newer version of your schema at a later point, first set a new
1409 C<$VERSION> in your Schema file, then:
1411 my $schema = My::Schema->connect($dsn);
1412 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
1418 This will produce new database-specific .sql files for the new version
1419 of the schema, plus scripts to convert from version 0.1 to 0.2. This
1420 requires that the files for 0.1 as created above are available in the
1421 given directory to diff against.
1423 =head2 Select from dual
1425 Dummy tables are needed by some databases to allow calling functions
1426 or expressions that aren't based on table content, for examples of how
1427 this applies to various database types, see:
1428 L<http://troels.arvin.dk/db/rdbms/#other-dummy_table>.
1430 Note: If you're using Oracles dual table don't B<ever> do anything
1431 other than a select, if you CRUD on your dual table you *will* break
1434 Make a table class as you would for any other table
1436 package MyAppDB::Dual;
1439 use base 'DBIx::Class::Core';
1440 __PACKAGE__->table("Dual");
1441 __PACKAGE__->add_columns(
1443 { data_type => "VARCHAR2", is_nullable => 0, size => 1 },
1446 Once you've loaded your table class select from it using C<select>
1447 and C<as> instead of C<columns>
1449 my $rs = $schema->resultset('Dual')->search(undef,
1450 { select => [ 'sydate' ],
1455 All you have to do now is be careful how you access your resultset, the below
1456 will not work because there is no column called 'now' in the Dual table class
1458 while (my $dual = $rs->next) {
1459 print $dual->now."\n";
1461 # Can't locate object method "now" via package "MyAppDB::Dual" at headshot.pl line 23.
1463 You could of course use 'dummy' in C<as> instead of 'now', or C<add_columns> to
1464 your Dual class for whatever you wanted to select from dual, but that's just
1465 silly, instead use C<get_column>
1467 while (my $dual = $rs->next) {
1468 print $dual->get_column('now')."\n";
1473 my $cursor = $rs->cursor;
1474 while (my @vals = $cursor->next) {
1475 print $vals[0]."\n";
1478 In case you're going to use this "trick" together with L<DBIx::Class::Schema/deploy> or
1479 L<DBIx::Class::Schema/create_ddl_dir> a table called "dual" will be created in your
1480 current schema. This would overlap "sys.dual" and you could not fetch "sysdate" or
1481 "sequence.nextval" anymore from dual. To avoid this problem, just tell
1482 L<SQL::Translator> to not create table dual:
1485 add_drop_table => 1,
1486 parser_args => { sources => [ grep $_ ne 'Dual', schema->sources ] },
1488 $schema->create_ddl_dir( [qw/Oracle/], undef, './sql', undef, $sqlt_args );
1490 Or use L<DBIx::Class::ResultClass::HashRefInflator>
1492 $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
1493 while ( my $dual = $rs->next ) {
1494 print $dual->{now}."\n";
1497 Here are some example C<select> conditions to illustrate the different syntax
1498 you could use for doing stuff like
1499 C<oracles.heavily(nested(functions_can('take', 'lots'), OF), 'args')>
1501 # get a sequence value
1502 select => [ 'A_SEQ.nextval' ],
1504 # get create table sql
1505 select => [ { 'dbms_metadata.get_ddl' => [ "'TABLE'", "'ARTIST'" ]} ],
1507 # get a random num between 0 and 100
1508 select => [ { "trunc" => [ { "dbms_random.value" => [0,100] } ]} ],
1511 select => [ { 'extract' => [ \'year from sysdate' ] } ],
1514 select => [ {'round' => [{'cos' => [ \'180 * 3.14159265359/180' ]}]}],
1516 # which day of the week were you born on?
1517 select => [{'to_char' => [{'to_date' => [ "'25-DEC-1980'", "'dd-mon-yyyy'" ]}, "'day'"]}],
1519 # select 16 rows from dual
1520 select => [ "'hello'" ],
1522 group_by => [ 'cube( 1, 2, 3, 4 )' ],
1526 =head2 Adding Indexes And Functions To Your SQL
1528 Often you will want indexes on columns on your table to speed up searching. To
1529 do this, create a method called C<sqlt_deploy_hook> in the relevant source
1530 class (refer to the advanced
1531 L<callback system|DBIx::Class::ResultSource/sqlt_deploy_callback> if you wish
1532 to share a hook between multiple sources):
1534 package My::Schema::Result::Artist;
1536 __PACKAGE__->table('artist');
1537 __PACKAGE__->add_columns(id => { ... }, name => { ... })
1539 sub sqlt_deploy_hook {
1540 my ($self, $sqlt_table) = @_;
1542 $sqlt_table->add_index(name => 'idx_name', fields => ['name']);
1547 Sometimes you might want to change the index depending on the type of the
1548 database for which SQL is being generated:
1550 my ($db_type = $sqlt_table->schema->translator->producer_type)
1551 =~ s/^SQL::Translator::Producer:://;
1553 You can also add hooks to the schema level to stop certain tables being
1560 sub sqlt_deploy_hook {
1561 my ($self, $sqlt_schema) = @_;
1563 $sqlt_schema->drop_table('table_name');
1566 You could also add views, procedures or triggers to the output using
1567 L<SQL::Translator::Schema/add_view>,
1568 L<SQL::Translator::Schema/add_procedure> or
1569 L<SQL::Translator::Schema/add_trigger>.
1572 =head2 Schema versioning
1574 The following example shows simplistically how you might use DBIx::Class to
1575 deploy versioned schemas to your customers. The basic process is as follows:
1581 Create a DBIx::Class schema
1593 Modify schema to change functionality
1597 Deploy update to customers
1601 B<Create a DBIx::Class schema>
1603 This can either be done manually, or generated from an existing database as
1604 described under L</Creating Schemas From An Existing Database>
1608 Call L<DBIx::Class::Schema/create_ddl_dir> as above under L</Creating DDL SQL>.
1610 B<Deploy to customers>
1612 There are several ways you could deploy your schema. These are probably
1613 beyond the scope of this recipe, but might include:
1619 Require customer to apply manually using their RDBMS.
1623 Package along with your app, making database dump/schema update/tests
1624 all part of your install.
1628 B<Modify the schema to change functionality>
1630 As your application evolves, it may be necessary to modify your schema
1631 to change functionality. Once the changes are made to your schema in
1632 DBIx::Class, export the modified schema and the conversion scripts as
1633 in L</Creating DDL SQL>.
1635 B<Deploy update to customers>
1637 Add the L<DBIx::Class::Schema::Versioned> schema component to your
1638 Schema class. This will add a new table to your database called
1639 C<dbix_class_schema_vesion> which will keep track of which version is installed
1640 and warn if the user tries to run a newer schema version than the
1641 database thinks it has.
1643 Alternatively, you can send the conversion SQL scripts to your
1646 =head2 Setting quoting for the generated SQL
1648 If the database contains column names with spaces and/or reserved words, they
1649 need to be quoted in the SQL queries. This is done using:
1651 $schema->storage->sql_maker->quote_char([ qw/[ ]/] );
1652 $schema->storage->sql_maker->name_sep('.');
1654 The first sets the quote characters. Either a pair of matching
1655 brackets, or a C<"> or C<'>:
1657 $schema->storage->sql_maker->quote_char('"');
1659 Check the documentation of your database for the correct quote
1660 characters to use. C<name_sep> needs to be set to allow the SQL
1661 generator to put the quotes the correct place, and defaults to
1662 C<.> if not supplied.
1664 In most cases you should set these as part of the arguments passed to
1665 L<DBIx::Class::Schema/connect>:
1667 my $schema = My::Schema->connect(
1677 In some cases, quoting will be required for all users of a schema. To enforce
1678 this, you can also overload the C<connection> method for your schema class:
1682 my $rv = $self->next::method( @_ );
1683 $rv->storage->sql_maker->quote_char([ qw/[ ]/ ]);
1684 $rv->storage->sql_maker->name_sep('.');
1688 =head2 Working with PostgreSQL array types
1690 You can also assign values to PostgreSQL array columns by passing array
1691 references in the C<\%columns> (C<\%vals>) hashref of the
1692 L<DBIx::Class::ResultSet/create> and L<DBIx::Class::Row/update> family of
1695 $resultset->create({
1696 numbers => [1, 2, 3]
1701 numbers => [1, 2, 3]
1708 In conditions (e.g. C<\%cond> in the L<DBIx::Class::ResultSet/search> family of
1709 methods) you cannot directly use array references (since this is interpreted as
1710 a list of values to be C<OR>ed), but you can use the following syntax to force
1711 passing them as bind values:
1715 numbers => \[ '= ?', [numbers => [1, 2, 3]] ]
1719 See L<SQL::Abstract/array_datatypes> and L<SQL::Abstract/Literal SQL with
1720 placeholders and bind values (subqueries)> for more explanation. Note that
1721 L<DBIx::Class> sets L<SQL::Abstract/bindtype> to C<columns>, so you must pass
1722 the bind values (the C<[1, 2, 3]> arrayref in the above example) wrapped in
1723 arrayrefs together with the column name, like this:
1724 C<< [column_name => value] >>.
1726 =head2 Formatting DateTime objects in queries
1728 To ensure C<WHERE> conditions containing L<DateTime> arguments are properly
1729 formatted to be understood by your RDBMS, you must use the C<DateTime>
1730 formatter returned by L<DBIx::Class::Storage::DBI/datetime_parser> to format
1731 any L<DateTime> objects you pass to L<search|DBIx::Class::ResultSet/search>
1732 conditions. Any L<Storage|DBIx::Class::Storage> object attached to your
1733 L<Schema|DBIx::Class::Schema> provides a correct C<DateTime> formatter, so
1734 all you have to do is:
1736 my $dtf = $schema->storage->datetime_parser;
1737 my $rs = $schema->resultset('users')->search(
1741 $dtf->format_datetime($dt_start),
1742 $dtf->format_datetime($dt_end),
1748 Without doing this the query will contain the simple stringification of the
1749 C<DateTime> object, which almost never matches the RDBMS expectations.
1751 This kludge is necessary only for conditions passed to
1752 L<DBIx::Class::ResultSet/search>, whereas
1753 L<create|DBIx::Class::ResultSet/create>,
1754 L<find|DBIx::Class::ResultSet/find>,
1755 L<DBIx::Class::Row/update> (but not L<DBIx::Class::ResultSet/update>) are all
1756 L<DBIx::Class::InflateColumn>-aware and will do the right thing when supplied
1757 an inflated C<DateTime> object.
1759 =head2 Using Unicode
1761 When using unicode character data there are two alternatives -
1762 either your database supports unicode characters (including setting
1763 the utf8 flag on the returned string), or you need to encode/decode
1764 data appropriately each time a string field is inserted into or
1765 retrieved from the database. It is better to avoid
1766 encoding/decoding data and to use your database's own unicode
1767 capabilities if at all possible.
1769 The L<DBIx::Class::UTF8Columns> component handles storing selected
1770 unicode columns in a database that does not directly support
1771 unicode. If used with a database that does correctly handle unicode
1772 then strange and unexpected data corrupt B<will> occur.
1774 The Catalyst Wiki Unicode page at
1775 L<http://wiki.catalystframework.org/wiki/tutorialsandhowtos/using_unicode>
1776 has additional information on the use of Unicode with Catalyst and
1779 The following databases do correctly handle unicode data:-
1783 MySQL supports unicode, and will correctly flag utf8 data from the
1784 database if the C<mysql_enable_utf8> is set in the connect options.
1786 my $schema = My::Schema->connection('dbi:mysql:dbname=test',
1788 { mysql_enable_utf8 => 1} );
1791 When set, a data retrieved from a textual column type (char,
1792 varchar, etc) will have the UTF-8 flag turned on if necessary. This
1793 enables character semantics on that string. You will also need to
1794 ensure that your database / table / column is configured to use
1795 UTF8. See Chapter 10 of the mysql manual for details.
1797 See L<DBD::mysql> for further details.
1801 Information about Oracle support for unicode can be found in
1802 L<DBD::Oracle/Unicode>.
1806 PostgreSQL supports unicode if the character set is correctly set
1807 at database creation time. Additionally the C<pg_enable_utf8>
1808 should be set to ensure unicode data is correctly marked.
1810 my $schema = My::Schema->connection('dbi:Pg:dbname=test',
1812 { pg_enable_utf8 => 1} );
1814 Further information can be found in L<DBD::Pg>.
1818 SQLite version 3 and above natively use unicode internally. To
1819 correctly mark unicode strings taken from the database, the
1820 C<sqlite_unicode> flag should be set at connect time (in versions
1821 of L<DBD::SQLite> prior to 1.27 this attribute was named
1824 my $schema = My::Schema->connection('dbi:SQLite:/tmp/test.db',
1826 { sqlite_unicode => 1} );
1828 =head1 BOOTSTRAPPING/MIGRATING
1830 =head2 Easy migration from class-based to schema-based setup
1832 You want to start using the schema-based approach to L<DBIx::Class>
1833 (see L<DBIx::Class::Manual::Intro/Setting it up manually>), but have an
1834 established class-based setup with lots of existing classes that you don't
1835 want to move by hand. Try this nifty script instead:
1838 use SQL::Translator;
1840 my $schema = MyDB->schema_instance;
1842 my $translator = SQL::Translator->new(
1843 debug => $debug || 0,
1844 trace => $trace || 0,
1845 no_comments => $no_comments || 0,
1846 show_warnings => $show_warnings || 0,
1847 add_drop_table => $add_drop_table || 0,
1848 validate => $validate || 0,
1850 'DBIx::Schema' => $schema,
1853 'prefix' => 'My::Schema',
1857 $translator->parser('SQL::Translator::Parser::DBIx::Class');
1858 $translator->producer('SQL::Translator::Producer::DBIx::Class::File');
1860 my $output = $translator->translate(@args) or die
1861 "Error: " . $translator->error;
1865 You could use L<Module::Find> to search for all subclasses in the MyDB::*
1866 namespace, which is currently left as an exercise for the reader.
1868 =head1 OVERLOADING METHODS
1870 L<DBIx::Class> uses the L<Class::C3> package, which provides for redispatch of
1871 method calls, useful for things like default values and triggers. You have to
1872 use calls to C<next::method> to overload methods. More information on using
1873 L<Class::C3> with L<DBIx::Class> can be found in
1874 L<DBIx::Class::Manual::Component>.
1876 =head2 Setting default values for a row
1878 It's as simple as overriding the C<new> method. Note the use of
1882 my ( $class, $attrs ) = @_;
1884 $attrs->{foo} = 'bar' unless defined $attrs->{foo};
1886 my $new = $class->next::method($attrs);
1891 For more information about C<next::method>, look in the L<Class::C3>
1892 documentation. See also L<DBIx::Class::Manual::Component> for more
1893 ways to write your own base classes to do this.
1895 People looking for ways to do "triggers" with DBIx::Class are probably
1896 just looking for this.
1898 =head2 Changing one field whenever another changes
1900 For example, say that you have three columns, C<id>, C<number>, and
1901 C<squared>. You would like to make changes to C<number> and have
1902 C<squared> be automagically set to the value of C<number> squared.
1903 You can accomplish this by wrapping the C<number> accessor with
1904 L<Class::Method::Modifiers>:
1906 around number => sub {
1907 my ($orig, $self) = (shift, shift);
1911 $self->squared( $value * $value );
1914 $self->next::method(@_);
1917 Note that the hard work is done by the call to C<next::method>, which
1918 redispatches your call to store_column in the superclass(es).
1920 Generally, if this is a calculation your database can easily do, try
1921 and avoid storing the calculated value, it is safer to calculate when
1922 needed, than rely on the data being in sync.
1924 =head2 Automatically creating related objects
1926 You might have a class C<Artist> which has many C<CD>s. Further, you
1927 want to create a C<CD> object every time you insert an C<Artist> object.
1928 You can accomplish this by overriding C<insert> on your objects:
1931 my ( $self, @args ) = @_;
1932 $self->next::method(@args);
1933 $self->create_related ('cds', \%initial_cd_data );
1937 If you want to wrap the two inserts in a transaction (for consistency,
1938 an excellent idea), you can use the awesome
1939 L<DBIx::Class::Storage::TxnScopeGuard>:
1942 my ( $self, @args ) = @_;
1944 my $guard = $self->result_source->schema->txn_scope_guard;
1946 $self->next::method(@args);
1947 $self->create_related ('cds', \%initial_cd_data );
1955 =head2 Wrapping/overloading a column accessor
1959 Say you have a table "Camera" and want to associate a description
1960 with each camera. For most cameras, you'll be able to generate the description from
1961 the other columns. However, in a few special cases you may want to associate a
1962 custom description with a camera.
1966 In your database schema, define a description field in the "Camera" table that
1967 can contain text and null values.
1969 In DBIC, we'll overload the column accessor to provide a sane default if no
1970 custom description is defined. The accessor will either return or generate the
1971 description, depending on whether the field is null or not.
1973 First, in your "Camera" schema class, define the description field as follows:
1975 __PACKAGE__->add_columns(description => { accessor => '_description' });
1977 Next, we'll define the accessor-wrapper subroutine:
1982 # If there is an update to the column, we'll let the original accessor
1984 return $self->_description(@_) if @_;
1986 # Fetch the column value.
1987 my $description = $self->_description;
1989 # If there's something in the description field, then just return that.
1990 return $description if defined $description && length $descripton;
1992 # Otherwise, generate a description.
1993 return $self->generate_description;
1996 =head1 DEBUGGING AND PROFILING
1998 =head2 DBIx::Class objects with Data::Dumper
2000 L<Data::Dumper> can be a very useful tool for debugging, but sometimes it can
2001 be hard to find the pertinent data in all the data it can generate.
2002 Specifically, if one naively tries to use it like so,
2006 my $cd = $schema->resultset('CD')->find(1);
2009 several pages worth of data from the CD object's schema and result source will
2010 be dumped to the screen. Since usually one is only interested in a few column
2011 values of the object, this is not very helpful.
2013 Luckily, it is possible to modify the data before L<Data::Dumper> outputs
2014 it. Simply define a hook that L<Data::Dumper> will call on the object before
2015 dumping it. For example,
2022 result_source => undef,
2030 local $Data::Dumper::Freezer = '_dumper_hook';
2032 my $cd = $schema->resultset('CD')->find(1);
2034 # dumps $cd without its ResultSource
2036 If the structure of your schema is such that there is a common base class for
2037 all your table classes, simply put a method similar to C<_dumper_hook> in the
2038 base class and set C<$Data::Dumper::Freezer> to its name and L<Data::Dumper>
2039 will automagically clean up your data before printing it. See
2040 L<Data::Dumper/EXAMPLES> for more information.
2044 When you enable L<DBIx::Class::Storage>'s debugging it prints the SQL
2045 executed as well as notifications of query completion and transaction
2046 begin/commit. If you'd like to profile the SQL you can subclass the
2047 L<DBIx::Class::Storage::Statistics> class and write your own profiling
2050 package My::Profiler;
2053 use base 'DBIx::Class::Storage::Statistics';
2055 use Time::HiRes qw(time);
2064 $self->print("Executing $sql: ".join(', ', @params)."\n");
2073 my $elapsed = sprintf("%0.4f", time() - $start);
2074 $self->print("Execution took $elapsed seconds.\n");
2080 You can then install that class as the debugging object:
2082 __PACKAGE__->storage->debugobj(new My::Profiler());
2083 __PACKAGE__->storage->debug(1);
2085 A more complicated example might involve storing each execution of SQL in an
2093 my $elapsed = time() - $start;
2094 push(@{ $calls{$sql} }, {
2100 You could then create average, high and low execution times for an SQL
2101 statement and dig down to see if certain parameters cause aberrant behavior.
2102 You might want to check out L<DBIx::Class::QueryLog> as well.
2104 =head1 IMPROVING PERFORMANCE
2110 Install L<Class::XSAccessor> to speed up L<Class::Accessor::Grouped>.
2114 On Perl 5.8 install L<Class::C3::XS>.
2118 L<prefetch|DBIx::Class::ResultSet/prefetch> relationships, where possible. See
2119 L</Using joins and prefetch>.
2123 Use L<populate|DBIx::Class::ResultSet/populate> in void context to insert data
2124 when you don't need the resulting L<DBIx::Class::Row> objects, if possible, but
2127 When inserting many rows, for best results, populate a large number of rows at a
2128 time, but not so large that the table is locked for an unacceptably long time.
2130 If using L<create|DBIx::Class::ResultSet/create> instead, use a transaction and
2131 commit every C<X> rows; where C<X> gives you the best performance without
2132 locking the table for too long.
2136 When selecting many rows, if you don't need full-blown L<DBIx::Class::Row>
2137 objects, consider using L<DBIx::Class::ResultClass::HashRefInflator>.
2141 See also L</STARTUP SPEED> and L</MEMORY USAGE> in this document.
2145 =head1 STARTUP SPEED
2147 L<DBIx::Class|DBIx::Class> programs can have a significant startup delay
2148 as the ORM loads all the relevant classes. This section examines
2149 techniques for reducing the startup delay.
2151 These tips are are listed in order of decreasing effectiveness - so the
2152 first tip, if applicable, should have the greatest effect on your
2155 =head2 Statically Define Your Schema
2158 L<DBIx::Class::Schema::Loader|DBIx::Class::Schema::Loader> to build the
2159 classes dynamically based on the database schema then there will be a
2160 significant startup delay.
2162 For production use a statically defined schema (which can be generated
2163 using L<DBIx::Class::Schema::Loader|DBIx::Class::Schema::Loader> to dump
2164 the database schema once - see
2165 L<make_schema_at|DBIx::Class::Schema::Loader/make_schema_at> and
2166 L<dump_directory|DBIx::Class::Schema::Loader/dump_directory> for more
2167 details on creating static schemas from a database).
2169 =head2 Move Common Startup into a Base Class
2171 Typically L<DBIx::Class> result classes start off with
2173 use base qw/DBIx::Class::Core/;
2174 __PACKAGE__->load_components(qw/InflateColumn::DateTime/);
2176 If this preamble is moved into a common base class:-
2180 use base qw/DBIx::Class::Core/;
2181 __PACKAGE__->load_components(qw/InflateColumn::DateTime/);
2184 and each result class then uses this as a base:-
2186 use base qw/MyDBICbase/;
2188 then the load_components is only performed once, which can result in a
2189 considerable startup speedup for schemas with many classes.
2191 =head2 Explicitly List Schema Result Classes
2193 The schema class will normally contain
2195 __PACKAGE__->load_classes();
2197 to load the result classes. This will use L<Module::Find|Module::Find>
2198 to find and load the appropriate modules. Explicitly defining the
2199 classes you wish to load will remove the overhead of
2200 L<Module::Find|Module::Find> and the related directory operations:
2202 __PACKAGE__->load_classes(qw/ CD Artist Track /);
2204 If you are instead using the L<load_namespaces|DBIx::Class::Schema/load_namespaces>
2205 syntax to load the appropriate classes there is not a direct alternative
2206 avoiding L<Module::Find|Module::Find>.
2210 =head2 Cached statements
2212 L<DBIx::Class> normally caches all statements with L<< prepare_cached()|DBI/prepare_cached >>.
2213 This is normally a good idea, but if too many statements are cached, the database may use too much
2214 memory and may eventually run out and fail entirely. If you suspect this may be the case, you may want
2215 to examine DBI's L<< CachedKids|DBI/CachedKidsCachedKids_(hash_ref) >> hash:
2217 # print all currently cached prepared statements
2218 print for keys %{$schema->storage->dbh->{CachedKids}};
2219 # get a count of currently cached prepared statements
2220 my $count = scalar keys %{$schema->storage->dbh->{CachedKids}};
2222 If it's appropriate, you can simply clear these statements, automatically deallocating them in the
2225 my $kids = $schema->storage->dbh->{CachedKids};
2226 delete @{$kids}{keys %$kids} if scalar keys %$kids > 100;
2228 But what you probably want is to expire unused statements and not those that are used frequently.
2229 You can accomplish this with L<Tie::Cache> or L<Tie::Cache::LRU>:
2233 my $schema = DB::Main->connect($dbi_dsn, $user, $pass, {
2234 on_connect_do => sub { tie %{shift->_dbh->{CachedKids}}, 'Tie::Cache', 100 },