=head1 NAME DBIx::Class::Manual::Cookbook - Miscellaneous recipes =head1 SEARCHING =head2 Paged results When you expect a large number of results, you can ask L for a paged resultset, which will fetch only a defined number of records at a time: my $rs = $schema->resultset('Artist')->search( undef, { page => 1, # page to return (defaults to 1) rows => 10, # number of results per page }, ); return $rs->all(); # all records for page 1 The C attribute does not have to be specified in your search: my $rs = $schema->resultset('Artist')->search( undef, { rows => 10, } ); return $rs->page(1); # DBIx::Class::ResultSet containing first 10 records In either of the above cases, you can get a L object for the resultset (suitable for use in e.g. a template) using the C method: return $rs->pager(); =head2 Complex WHERE clauses Sometimes you need to formulate a query using specific operators: my @albums = $schema->resultset('Album')->search({ artist => { 'like', '%Lamb%' }, title => { 'like', '%Fear of Fours%' }, }); This results in something like the following C clause: WHERE artist LIKE '%Lamb%' AND title LIKE '%Fear of Fours%' Other queries might require slightly more complex logic: my @albums = $schema->resultset('Album')->search({ -or => [ -and => [ artist => { 'like', '%Smashing Pumpkins%' }, title => 'Siamese Dream', ], artist => 'Starchildren', ], }); This results in the following C clause: WHERE ( artist LIKE '%Smashing Pumpkins%' AND title = 'Siamese Dream' ) OR artist = 'Starchildren' For more information on generating complex queries, see L. =head2 Arbitrary SQL through a custom ResultSource Sometimes you have to run arbitrary SQL because your query is too complex (e.g. it contains Unions, Sub-Selects, Stored Procedures, etc.) or has to be optimized for your database in a special way, but you still want to get the results as a L. The recommended way to accomplish this is by defining a separate ResultSource for your query. You can then inject complete SQL statements using a scalar reference (this is a feature of L). Say you want to run a complex custom query on your user data, here's what you have to add to your User class: package My::Schema::User; use base qw/DBIx::Class/; # ->load_components, ->table, ->add_columns, etc. # Make a new ResultSource based on the User class my $source = __PACKAGE__->result_source_instance(); my $new_source = $source->new( $source ); $new_source->source_name( 'UserFriendsComplex' ); # Hand in your query as a scalar reference # It will be added as a sub-select after FROM, # so pay attention to the surrounding brackets! $new_source->name( \<register_source( 'UserFriendsComplex' => $new_source ); Next, you can execute your complex query using bind parameters like this: my $friends = [ $schema->resultset( 'UserFriendsComplex' )->search( {}, { bind => [ 12345, 12345 ] } ) ]; ... and you'll get back a perfect L. =head2 Using specific columns When you only want specific columns from a table, you can use C to specify which ones you need. This is useful to avoid loading columns with large amounts of data that you aren't about to use anyway: my $rs = $schema->resultset('Artist')->search( undef, { columns => [qw/ name /] } ); # Equivalent SQL: # SELECT artist.name FROM artist This is a shortcut for C and C. =head2 Using database functions or stored procedures The combination of C to specify the source for your column value (e.g. a column name, function, or stored procedure name). You then use C to set the column name you will use to access the returned value: my $rs = $schema->resultset('Artist')->search( {}, { select => [ 'name', { LENGTH => 'name' } ], as => [qw/ name name_length /], } ); # Equivalent SQL: # SELECT name name, LENGTH( name ) # FROM artist Note that the C< as > attribute has absolutely nothing to with the sql syntax C< SELECT foo AS bar > (see the documentation in L). If your alias exists as a column in your base class (i.e. it was added with C), you just access it as normal. Our C class has a C column, so we just use the C accessor: my $artist = $rs->first(); my $name = $artist->name(); If on the other hand the alias does not correspond to an existing column, you have to fetch the value using the C accessor: my $name_length = $artist->get_column('name_length'); If you don't like using C, you can always create an accessor for any of your aliases using either of these: # Define accessor manually: sub name_length { shift->get_column('name_length'); } # Or use DBIx::Class::AccessorGroup: __PACKAGE__->mk_group_accessors('column' => 'name_length'); =head2 SELECT DISTINCT with multiple columns my $rs = $schema->resultset('Foo')->search( {}, { select => [ { distinct => [ $source->columns ] } ], as => [ $source->columns ] # remember 'as' is not the same as SQL AS :-) } ); =head2 SELECT COUNT(DISTINCT colname) my $rs = $schema->resultset('Foo')->search( {}, { select => [ { count => { distinct => 'colname' } } ], as => [ 'count' ] } ); my $count = $rs->next->get_column('count'); =head2 Grouping results L supports C as follows: my $rs = $schema->resultset('Artist')->search( {}, { join => [qw/ cds /], select => [ 'name', { count => 'cds.cdid' } ], as => [qw/ name cd_count /], group_by => [qw/ name /] } ); # Equivalent SQL: # SELECT name, COUNT( cds.cdid ) FROM artist me # LEFT JOIN cd cds ON ( cds.artist = me.artistid ) # GROUP BY name Please see L documentation if you are in any way unsure about the use of the attributes above (C< join >, C< select >, C< as > and C< group_by >). =head2 Predefined searches You can write your own L class by inheriting from it and define often used searches as methods: package My::DBIC::ResultSet::CD; use strict; use warnings; use base 'DBIx::Class::ResultSet'; sub search_cds_ordered { my ($self) = @_; return $self->search( {}, { order_by => 'name DESC' }, ); } 1; To use your resultset, first tell DBIx::Class to create an instance of it for you, in your My::DBIC::Schema::CD class: # class definition as normal __PACKAGE__->load_components(qw/ Core /); __PACKAGE__->table('cd'); # tell DBIC to use the custom ResultSet class __PACKAGE__->resultset_class('My::DBIC::ResultSet::CD'); Note that C must be called after C and C, or you will get errors about missing methods. Then call your new method in your code: my $ordered_cds = $schema->resultset('CD')->search_cds_ordered(); =head2 Using SQL functions on the left hand side of a comparison Using SQL functions on the left hand side of a comparison is generally not a good idea since it requires a scan of the entire table. However, it can be accomplished with C when necessary. If you do not have quoting on, simply include the function in your search specification as you would any column: $rs->search({ 'YEAR(date_of_birth)' => 1979 }); With quoting on, or for a more portable solution, use the C attribute: $rs->search({}, { where => \'YEAR(date_of_birth) = 1979' }); =begin hidden (When the bind args ordering bug is fixed, this technique will be better and can replace the one above.) With quoting on, or for a more portable solution, use the C and C attributes: $rs->search({}, { where => \'YEAR(date_of_birth) = ?', bind => [ 1979 ] }); =end hidden =head1 JOINS AND PREFETCHING =head2 Using joins and prefetch You can use the C attribute to allow searching on, or sorting your results by, one or more columns in a related table. To return all CDs matching a particular artist name: my $rs = $schema->resultset('CD')->search( { 'artist.name' => 'Bob Marley' }, { join => [qw/artist/], # join the artist table } ); # Equivalent SQL: # SELECT cd.* FROM cd # JOIN artist ON cd.artist = artist.id # WHERE artist.name = 'Bob Marley' If required, you can now sort on any column in the related tables by including it in your C attribute: my $rs = $schema->resultset('CD')->search( { 'artist.name' => 'Bob Marley' }, { join => [qw/ artist /], order_by => [qw/ artist.name /] } ); # Equivalent SQL: # SELECT cd.* FROM cd # JOIN artist ON cd.artist = artist.id # WHERE artist.name = 'Bob Marley' # ORDER BY artist.name Note that the C attribute should only be used when you need to search or sort using columns in a related table. Joining related tables when you only need columns from the main table will make performance worse! Now let's say you want to display a list of CDs, each with the name of the artist. The following will work fine: while (my $cd = $rs->next) { print "CD: " . $cd->title . ", Artist: " . $cd->artist->name; } There is a problem however. We have searched both the C and C tables in our main query, but we have only returned data from the C table. To get the artist name for any of the CD objects returned, L will go back to the database: SELECT artist.* FROM artist WHERE artist.id = ? A statement like the one above will run for each and every CD returned by our main query. Five CDs, five extra queries. A hundred CDs, one hundred extra queries! Thankfully, L has a C attribute to solve this problem. This allows you to fetch results from related tables in advance: my $rs = $schema->resultset('CD')->search( { 'artist.name' => 'Bob Marley' }, { join => [qw/ artist /], order_by => [qw/ artist.name /], prefetch => [qw/ artist /] # return artist data too! } ); # Equivalent SQL (note SELECT from both "cd" and "artist"): # SELECT cd.*, artist.* FROM cd # JOIN artist ON cd.artist = artist.id # WHERE artist.name = 'Bob Marley' # ORDER BY artist.name The code to print the CD list remains the same: while (my $cd = $rs->next) { print "CD: " . $cd->title . ", Artist: " . $cd->artist->name; } L has now prefetched all matching data from the C table, so no additional SQL statements are executed. You now have a much more efficient query. Note that as of L 0.05999_01, C I be used with C relationships. Also note that C should only be used when you know you will definitely use data from a related table. Pre-fetching related tables when you only need columns from the main table will make performance worse! =head2 Multi-step joins Sometimes you want to join more than one relationship deep. In this example, we want to find all C objects who have Cs whose C contain a specific string: # Relationships defined elsewhere: # Artist->has_many('cds' => 'CD', 'artist'); # CD->has_one('liner_notes' => 'LinerNotes', 'cd'); my $rs = $schema->resultset('Artist')->search( { 'liner_notes.notes' => { 'like', '%some text%' }, }, { join => { 'cds' => 'liner_notes' } } ); # Equivalent SQL: # SELECT artist.* FROM artist # JOIN ( cd ON artist.id = cd.artist ) # JOIN ( liner_notes ON cd.id = liner_notes.cd ) # WHERE liner_notes.notes LIKE '%some text%' Joins can be nested to an arbitrary level. So if we decide later that we want to reduce the number of Artists returned based on who wrote the liner notes: # Relationship defined elsewhere: # LinerNotes->belongs_to('author' => 'Person'); my $rs = $schema->resultset('Artist')->search( { 'liner_notes.notes' => { 'like', '%some text%' }, 'author.name' => 'A. Writer' }, { join => { 'cds' => { 'liner_notes' => 'author' } } } ); # Equivalent SQL: # SELECT artist.* FROM artist # JOIN ( cd ON artist.id = cd.artist ) # JOIN ( liner_notes ON cd.id = liner_notes.cd ) # JOIN ( author ON author.id = liner_notes.author ) # WHERE liner_notes.notes LIKE '%some text%' # AND author.name = 'A. Writer' =head2 Multi-step prefetch From 0.04999_05 onwards, C can be nested more than one relationship deep using the same syntax as a multi-step join: my $rs = $schema->resultset('Tag')->search( {}, { prefetch => { cd => 'artist' } } ); # Equivalent SQL: # SELECT tag.*, cd.*, artist.* FROM tag # JOIN cd ON tag.cd = cd.cdid # JOIN artist ON cd.artist = artist.artistid Now accessing our C and C relationships does not need additional SQL statements: my $tag = $rs->first; print $tag->cd->artist->name; =head1 ROW-LEVEL OPERATIONS =head2 Retrieving a row object's Schema It is possible to get a Schema object from a row object like so: my $schema = $cd->result_source->schema; # use the schema as normal: my $artist_rs = $schema->resultset('Artist'); This can be useful when you don't want to pass around a Schema object to every method. =head2 Getting the value of the primary key for the last database insert AKA getting last_insert_id If you are using PK::Auto (which is a core component as of 0.07), this is straightforward: my $foo = $rs->create(\%blah); # do more stuff my $id = $foo->id; # foo->my_primary_key_field will also work. If you are not using autoincrementing primary keys, this will probably not work, but then you already know the value of the last primary key anyway. =head2 Stringification Employ the standard stringification technique by using the C module. To make an object stringify itself as a single column, use something like this (replace C with the column/method of your choice): use overload '""' => sub { shift->name}, fallback => 1; For more complex stringification, you can use an anonymous subroutine: use overload '""' => sub { $_[0]->name . ", " . $_[0]->address }, fallback => 1; =head3 Stringification Example Suppose we have two tables: C and C. The table specifications are: Product(id, Description, category) Category(id, Description) C is a foreign key into the Category table. If you have a Product object C<$obj> and write something like print $obj->category things will not work as expected. To obtain, for example, the category description, you should add this method to the class defining the Category table: use overload "" => sub { my $self = shift; return $self->Description; }, fallback => 1; =head2 Want to know if find_or_create found or created a row? Just use C instead, then check C: my $obj = $rs->find_or_new({ blah => 'blarg' }); unless ($obj->in_storage) { $obj->insert; # do whatever else you wanted if it was a new row } =head2 Dynamic Sub-classing DBIx::Class proxy classes AKA multi-class object inflation from one table L classes are proxy classes, therefore some different techniques need to be employed for more than basic subclassing. In this example we have a single user table that carries a boolean bit for admin. We would like like to give the admin users objects(L) the same methods as a regular user but also special admin only methods. It doesn't make sense to create two seperate proxy-class files for this. We would be copying all the user methods into the Admin class. There is a cleaner way to accomplish this. Overriding the C method within the User proxy-class gives us the effect we want. This method is called by L when inflating a result from storage. So we grab the object being returned, inspect the values we are looking for, bless it if it's an admin object, and then return it. See the example below: B package DB::Schema; use base qw/DBIx::Class::Schema/; __PACKAGE__->load_classes(qw/User/); B package DB::Schema::User; use strict; use warnings; use base qw/DBIx::Class/; ### Defined what our admin class is for ensure_class_loaded my $admin_class = __PACKAGE__ . '::Admin'; __PACKAGE__->load_components(qw/Core/); __PACKAGE__->table('users'); __PACKAGE__->add_columns(qw/user_id email password firstname lastname active admin/); __PACKAGE__->set_primary_key('user_id'); sub inflate_result { my $self = shift; my $ret = $self->next::method(@_); if( $ret->admin ) {### If this is an admin rebless for extra functions $self->ensure_class_loaded( $admin_class ); bless $ret, $admin_class; } return $ret; } sub hello { print "I am a regular user.\n"; return ; } package DB::Schema::User::Admin; use strict; use warnings; use base qw/DB::Schema::User/; sub hello { print "I am an admin.\n"; return; } sub do_admin_stuff { print "I am doing admin stuff\n"; return ; } B test.pl use warnings; use strict; use DB::Schema; my $user_data = { email => 'someguy@place.com', password => 'pass1', admin => 0 }; my $admin_data = { email => 'someadmin@adminplace.com', password => 'pass2', admin => 1 }; my $schema = DB::Schema->connection('dbi:Pg:dbname=test'); $schema->resultset('User')->create( $user_data ); $schema->resultset('User')->create( $admin_data ); ### Now we search for them my $user = $schema->resultset('User')->single( $user_data ); my $admin = $schema->resultset('User')->single( $admin_data ); print ref $user, "\n"; print ref $admin, "\n"; print $user->password , "\n"; # pass1 print $admin->password , "\n";# pass2; inherited from User print $user->hello , "\n";# I am a regular user. print $admin->hello, "\n";# I am an admin. ### The statement below will NOT print print "I can do admin stuff\n" if $user->can('do_admin_stuff'); ### The statement below will print print "I can do admin stuff\n" if $admin->can('do_admin_stuff'); =head2 Skip object creation for faster results DBIx::Class is not built for speed, it's built for convenience and ease of use, but sometimes you just need to get the data, and skip the fancy objects. To do this simply use L. my $rs = $schema->resultset('CD'); $rs->result_class('DBIx::Class::ResultClass::HashRefInflator'); my $hash_ref = $rs->find(1); Wasn't that easy? =head2 Get raw data for blindingly fast results If the L solution above is not fast enough for you, you can use a DBIx::Class to return values exactly as they come out of the data base with none of the convenience methods wrapped round them. This is used like so:- my $cursor = $rs->cursor while (my @vals = $cursor->next) { # use $val[0..n] here } You will need to map the array offsets to particular columns (you can use the I and C instead of C my $rs = $schema->resultset('Dual')->search(undef, { select => [ 'sydate' ], as => [ 'now' ] }, ); All you have to do now is be careful how you access your resultset, the below will not work because there is no column called 'now' in the Dual table class while (my $dual = $rs->next) { print $dual->now."\n"; } # Can't locate object method "now" via package "MyAppDB::Dual" at headshot.pl line 23. You could of course use 'dummy' in C instead of 'now', or C to your Dual class for whatever you wanted to select from dual, but that's just silly, instead use C while (my $dual = $rs->next) { print $dual->get_column('now')."\n"; } Or use C my $cursor = $rs->cursor; while (my @vals = $cursor->next) { print $vals[0]."\n"; } Or use L $rs->result_class('DBIx::Class::ResultClass::HashRefInflator'); while ( my $dual = $rs->next ) { print $dual->{now}."\n"; } Here are some example C