NAME

DBIx::Class::Manual::Joining - Manual on joining tables with DBIx::Class

DESCRIPTION

This document should help you to use DBIx::Class if you are trying to convert your normal SQL queries into DBIx::Class based queries, if you use joins extensively (and also probably if you don't).

WHAT ARE JOINS

If you ended up here and you don't actually know what joins are yet, then you should likely try the DBIx::Class::Manual::Intro instead. Skip this part if you know what joins are..

But I'll explain anyway. Assuming you have created your database in a more or less sensible way, you will end up with several tables that contain related information. For example, you may have a table containing information about CDs, containing the CD title and it's year of publication, and another table containing all the Tracks for the CDs, one track per row.

When you wish to extract information about a particular CD and all it's tracks, You can either fetch the CD row, then make another query to fetch the tracks, or you can use a join. Compare:

SELECT ID, Title, Year FROM CD WHERE Title = 'Funky CD';
# .. Extract the ID, which is 10
SELECT Name, Artist FROM Tracks WHERE CDID = 10;

SELECT cd.ID, cd.Title, cd.Year, tracks.Name, tracks.Artist FROM CD JOIN Tracks ON CD.ID = tracks.CDID WHERE cd.Title = 'Funky CD';

So, joins are a way of extending simple select statements to include fields from other, related, tables. There are various types of joins, depending on which combination of the data you wish to retrieve, see MySQL's doc on JOINs: http://dev.mysql.com/doc/refman/5.0/en/join.html.

DEFINING JOINS AND RELATIONSHIPS

In DBIx::Class each relationship between two tables needs to first be defined in the ResultSource for the table. If the relationship needs to be accessed in both directions (i.e. Fetch all tracks of a CD, and fetch the CD data for a Track), then it needs to be defined in both tables.

For the CDs/Tracks example, that means writing, in MySchema::CD:

MySchema::CD->has_many('tracks', 'MySchema::Tracks');

And in MySchema::Tracks:

MySchema::Tracks->belongs_to('cd', 'MySchema::CD', 'CDID');

There are several other types of relationships, they are more comprehensively described in DBIx::Class::Relationship.

USING JOINS

Once you have defined all your relationships, using them in actual joins is fairly simple. The type of relationship that you chose e.g. has_many, already indicates what sort of join will be performed. has_many produces a LEFT JOIN for example, which will fetch all the rows on the left side, whether there are matching rows on the right (table being joined to), or not. You can force other types of joins in your relationship, see the DBIx::Class::Relationship docs.

When performing either a search or a find operation, you can specify which relations to also fetch data from (or sort by), using the join attribute, like this:

$schema->resultset('CD')->search(
  { 'Title' => 'Funky CD' },
  { join      => 'tracks',
    '+select' => [ 'tracks.Name', 'tracks.Artist' ],
    '+as'     => [ 'TrackName', 'ArtistName' ]
  }
);

If you don't recognise most of this syntax, you should probably go read "search" in DBIx::Class::ResultSet and "ATTRIBUTES" in DBIx::Class::ResultSet, but here's a quick break down:

The first argument to search is a hashref of the WHERE attributes, in this case a simple restriction on the Title column. The second argument is a hashref of attributes to the search, '+select' adds extra columns to the select (from the joined table(s) or from calculations), and '+as' gives aliases to those fields.

'join' specifies which relationships to include in the query. The distinction between relationships and tables is important here, only the relationship names are valid.

This example should magically produce SQL like the second select in "WHAT ARE JOINS" above.

COMPLEX JOINS AND STUFF

Across multiple relations

For simplicity in the example above, the Artist was shown as a simple text field in the Tracks table, in reality, you'll want to have the artists in their own table as well, thus to fetch the complete set of data we'll need to join to the Artist table too.

In MySchema::Tracks:

MySchema::Tracks->belongs_to('artist', 'MySchema::Artist', 'ArtistID');

The search:

$schema->resultset('CD')->search(
  { 'Title' => 'Funky CD' },
  { join      => { 'tracks' => 'artist' },
    '+select' => [ 'tracks.Name', 'artist.Artist' ],
    '+as'     => [ 'TrackName', 'ArtistName' ]
  }
);

Which is:

SELECT me.ID, me.Title, me.Year, tracks.Name, artist.Artist FROM CD me JOIN Tracks tracks ON CD.ID = tracks.CDID JOIN Artists artist ON tracks.ArtistID = artist.ID WHERE me.Title = 'Funky CD';

To perform joins using relations of the tables you are joining to, use a hashref to indicate the join depth. This can theoretically go as deep as you like (warning, contrived examples!):

join => { room => { table => 'leg' } }

To join two relations at the same level, use an arrayref instead:

join => { room => [ 'chair', 'table' ] } 

Or combine the two:

join => { room => [ 'chair', { table => 'leg' } ]

Table aliases

As an aside to all the discussion on joins, note that DBIx::Class uses the relation names as table aliases. This is important when you need to add grouping or ordering to your queries:

$schema->resultset('CD')->search(
  { 'Title' => 'Funky CD' },
  { join      => { 'tracks' => 'artist' },
    order_by  => [ 'tracks.Name', 'artist.Artist' ],
    '+select' => [ 'tracks.Name', 'artist.Artist' ],
    '+as'     => [ 'TrackName', 'ArtistName' ]
  }
);

SELECT me.ID, me.Title, me.Year, tracks.Name, artist.Artist FROM CD me JOIN Tracks tracks ON CD.ID = tracks.CDID JOIN Artists artist ON tracks.ArtistID = artist.ID WHERE me.Title = 'Funky CD' ORDER BY tracks.Name, artist.Artist;

This is essential if any of your tables have columns with the same names.

Note that the table of the resultsource the search was performed on, is always aliased to me.

Joining to the same table twice

There is no magic to this, just do it. The table aliases will automatically be numbered:

join => [ 'room', 'room' ]

The aliases are: room and room_2.