Remove spare comment
[dbsrgits/DBIx-Class-Manual-SQLHackers.git] / lib / DBIx / Class / Manual / SQLHackers / SELECT.pod
CommitLineData
6c2a4396 1=head1 NAME
2
3DBIx::Class::Manual::SQLHackers::SELECT - DBIx::Class for SQL Hackers - SELECT
4
5=over
6
7=item L<Introduction|DBIx::Class::Manual::SQLHackers::Introduction>
8
9=item L<CREATE|DBIx::Class::Manual::SQLHackers::CREATE>
10
11=item L<INSERT|DBIx::Class::Manual::SQLHackers::INSERT>
12
13=item SELECT
14
15=item L<UPDATE|DBIx::Class::Manual::SQLHackers::UPDATE>
16
17=item L<DELETE|DBIx::Class::Manual::SQLHackers::DELETE>
18
19=item L<BEGIN, COMMIT|DBIx::Class::Manual::SQLHackers::Transactions>
20
21=back
22
23=head1 SELECTing data
24
25=head2 Fetching rows from a query
26
27 SELECT id, username, dob, realname, password
28 FROM users;
29
30In DBIx::Class queries are represented by ResultSet objects. These are created by calling B<search> on existing resultsets, passing new search conditions. A query is not run against the database until data is explicitly requested.
31
32You can either fetch all the data at once, or iterate over the results:
33
34=over
35
36=item 1. Create a Schema object representing the database you are working with:
37
38 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
39
abc32120 40=item 2. The B<resultset> method returns a ResultSet representing a query with no conditions on the given B<ResultSource>:
6c2a4396 41
42 my $user_resultset = $schema->resultset('User');
43
44=item 3. Fetch all users as Row objects using the B<all> method:
45
46 my @users = $user_resultset->all();
47
48=item 4. OR, fetch each user as a Row object using B<next>:
49
50 while( my $user = $user_resultset->next()) {
51 }
52
53=back
54
55=head2 Fetching column values from a Row object
56
57The Row object represents the results from a single data source table in the query. The column values can be retrieved by using the accessor methods named after the column names. (By default that is, accessors can be changed in the L<Result Class|DBIx::Class::ResulSource> if needed).
58
59 print $user->username;
60
abc32120 61See the L<DBIx::Class::Row> documentation for more things you can do
6c2a4396 62with Row objects.
63
64=head2 Simple SELECT, one row via the primary key
65
66 SELECT id, username, dob, realname, password
67 FROM users
68 WHERE id = 1;
69
70The B<find> method on a ResultSet is a shortcut to create a query based on the inputs, run the query, and return a single row as a Row object result.
71
72If passed a condition which matches multiple rows, a warning is given.
73
74=over
75
76=item 1. Create a Schema object representing the database you are working with:
77
78 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
79
80=item 2. Call the B<find> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
81
82 my $fred_user = $schema->resultset('User')->find({ id => 1 });
83
84=back
85
86B<$fred_user> is a now Row object.
87
88=head2 Simple SELECT, one row via a unique key
89
90 SELECT id, username, dob, realname, password
91 FROM users
92 WHERE username = 'fredbloggs';
93
abc32120 94B<find> also works well on unique constraints, for example the username of our user. Unique constraints can be defined on Result classes using B<add_unique_constraint> (See L<CREATE|DBIx::Class::Manual::SQLHackers::CREATE>).
6c2a4396 95
96=over
97
98=item 1. Create a Schema object representing the database you are working with:
99
100 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
101
102=item 2. Call the B<find> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
103
104 my $fred_user = $schema->resultset('User')->find(
105 { username => 'fredbloggs' },
106 { key => 'uniq_username' }
107 );
108
109=back
110
111"uniq_username" is the name of a constraint defined on the User L<ResultSource|DBIx::Class::ResultSource> which specifies that the username column is unique across the table. The second argument to B<find> is a set of attributes, of which the "key" attribute defines which constraint to do a lookup on.
112
113=head2 Simple SELECT, with WHERE condition
114
115 SELECT id, username, dob, realname, password
116 FROM users
117 WHERE dob = '1910-02-01';
118
119To select all users born on the date '1910-02-01', we can use the B<search> method to prepare a query. Search returns a new resultset with the search conditions stored in it, it does not run the query on the database.
120
121=over
122
123=item 1. Create a Schema object representing the database you are working with:
124
125 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
126
127=item 2. Call the B<search> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
128
129 my $dob_search = $schema->resultset('User')->search(
130 { dob => '1910-02-01' }
131 );
132
133=back
134
abc32120 135To run the query, use the B<all> or B<next> methods shown at the beginning of this page.
6c2a4396 136
137=head2 SELECT with different WHERE conditions
138
139Below are shown some common SQL where conditions. The syntax for these is parsed by a module called L<SQL::Abstract> which DBIx::Class uses. They can all be passed to the B<search> method as conditions.
140
141 SELECT id, username, dob, realname, password
142 FROM users
143 WHERE username LIKE 'fred%';
144
145 my $name_search = $schema->resultset('User')->search(
146 { username => { '-like' => 'fred%' } }
147 );
148
149 SELECT id, username, dob, realname, password
150 FROM users
151 WHERE dob BETWEEN '1910-01-01' AND '1910-12-31';
152
153 my $year_dob_search = $schema->resultset('User')->search(
154 { dob => { '-between' => ['1910-01-01', '1910-12-31'] } }
155 );
156
157 SELECT id, username, dob, realname, password
158 FROM users
159 WHERE dob IN ('1910-02-01', '1910-02-02');
160
161 my $feb_dob_search = $schema->resultset('User')->search(
162 { dob => { '-in' => ['1910-02-01', '1910-02-02'] } }
163 );
164
165 SELECT id, username, dob, realname, password
166 FROM users
167 WHERE dob >= 1911-01-01;
168
169 my $next_year_dob = $schema->resultset('User')->search(
170 { dob => { '>=', '1911-01-01' } }
171 );
172
173
174=head2 SELECT with WHERE condition on JOINed table
175
176 SELECT posts.id, created_date, title, post
177 FROM posts
178 JOIN users user ON user.id = posts.user_id
179 WHERE user.username = 'fredbloggs';
180
181The second argument to B<search> is a hashref of attributes to apply to the query. One of them is B<join>, which is used to connect to other tables using the relationships defined in the Result classes.
182
183=over
184
185=item 1. Create a Schema object representing the database you are working with:
186
187 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
188
189=item 2. Call the B<search> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
190
191 my $freds_posts = $schema->resultset('Post')->search(
192 { 'user.username' => 'fredbloggs' },
193 { join => 'user' }
194 );
195
196=back
197
198Note that the string "user", used twice here, refers to the B<name> of the L<Relationship|DBIx::Class::Manual::SQLHackers::CREATE> between the "Post" source and the "User" source. All dealings with related tables are refered to by relationship names, not table names.
199
200To run the query, use the B<all> or B<next> methods show at the beginning of this page.
201
202=head2 SELECT with fewer columns
203
204 SELECT id, title
205 FROM posts
206
207There's usually little reason to do this sort of query, as fetching all the data in a row doesn't cost any more time than fetching some of it. Unless of course your source is a View with calculations, or has huge blobs, or.. Okay, you might well want to do this occasionally.
208
6c2a4396 209=over
210
211=item 1. Create a Schema object representing the database you are working with:
212
213 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
214
215=item 2. Call the B<search> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
216
217 my $post_titles = $schema->resultset('Post')->search(
218 { },
219 { columns => [qw/id title/] }
220 );
221
222=back
223
abc32120 224Note that accessors for other columns not fetched will return B<undef>, which is also the perl equivalent of the SQL C<NULL> value. To discover whether a columns data has been loaded or not, use L<DBIx::Class::Row/has_column_loaded>.
6c2a4396 225
226
227=head2 SELECT with aggregates
228
229 SELECT COUNT(*)
230 FROM users;
231
232To find out how many users exist. This simple one can be achieved with a built-in method, B<count>.
233
234=over
235
236=item 1. Create a Schema object representing the database you are working with:
237
238 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
239
240=item 2. Call the *count* method on the resultset for the [Source] you wish to fetch data from:
241
242 my $posts_count = $schema->resultset('Post')->count();
243
244=back
245
246The result is not an object, just a number.
247
248 SELECT SUM(amount)
249 FROM prices;
250
251A rather pointless exercise in summing an entire "amount" column from an imaginary "prices" table. This can be done in several ways, first, the built-in L<DBIx::Class::ResultSet::Column> method, by calling B<get_column>.
252
253=over
254
255=item 1. Create a Schema object representing the database you are working with:
256
257 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
258
259=item 2. Call the B<get_column> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from, then the B<sum> method:
260
261 my $sum_prices = $schema->resultset('Price')->get_column('amount')
262 ->sum();
263
264=back
265
266The result is just a number.
267
268The alternate way uses the B<search> method and is easier to build further refinements into.
269
270=over
271
272=item 1. Create a Schema object representing the database you are working with:
273
274 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
275
276=item 2. Call the B<search> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
277
278 my $sum_prices_rs = $schema->resultset('Price')->search(
279 { },
abc32120 280 { columns => { sum_amount => { SUM => 'amount'} } },
6c2a4396 281 );
282
283=back
284
285The result is a resultset. To fetch the one-row result, call B<single> or B<all>. The resulting Row object will not contain an accessor for the virtual "sum_amount" column, we'll need to fetch it using the Row method B<get_column>.
286
287 print $sum_prices_rs->single->get_column('sum_amount');
288
289=head2 SELECT from JOINed tables
290
291 SELECT users.id, username, posts.id, posts.title
292 FROM users
293 JOIN posts posts ON posts.used_id = users.id
294
295To select data from other tables, use the B<join> attribute to name the table relationships to create a JOIN clause to.
296
297=over
298
299=item 1. Create a Schema object representing the database you are working with:
300
301 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
302
303=item 2. Call the B<search> method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to group data on:
304
305 my $posts_count_per_user = $schema->resultset('User')->search(
306 { },
abc32120 307 { columns => [ qw/id username posts.id posts.title/ ],
6c2a4396 308 join => 'posts',
309 }
310 );
311
312=back
313
314Here "posts" refers to the name of the L<Relationship|DBIx::Class::Relationship> between the "User" source and the "Post" source.
315
316To retrieve the extra data, call the usual relationship accessor:
317
318 while( my $row = $sorted_users->next) {
319 print "user/post: ", $row->username;
320 print $_->title for $row->posts;
321 print "\n";
322 }
323
324
325=head2 SELECT with GROUP BY
326
327 SELECT users.id, username, COUNT(posts.id)
328 FROM users
329 JOIN posts posts ON posts.used_id = users.id
330 GROUP BY users.id, username;
331
abc32120 332To group your results, use the B<group_by> attribute on a B<search> method. We also use the B<columns> attribute to select and name a subset of columns.
6c2a4396 333
334=over
335
336=item 1. Create a Schema object representing the database you are working with:
337
338 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
339
340=item 2. Call the *search* method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to group data on:
341
342 my $posts_count_per_user = $schema->resultset('User')->search(
343 { },
abc32120 344 { columns => [ qw/id username/, { post_count => { count => 'posts.id' } } ],
6c2a4396 345 join => 'posts',
346 group_by => [qw/id username/],
347 }
348 );
349
350=back
351
352Here "posts" refers to the name of the L<Relationship|DBIx::Class::Relationship> between the "User" source and the "Post" source.
353
354The results will contain two columns with the usual accessors, "id" and "username", and one with no accessor, as it is a virtual column.
355
356 while( my $row = $posts_count_per_user->next) {
357 print "user: ", $row->username, " posts: ", $row->get_column('post_count');
358 }
359
360Note: Remember to disambiguate the columns when joining two tables with identical column names.
361
362=head2 SELECT with simple ORDER BY
363
364 SELECT users.id, username, dob, realname, password, posts.title
365 FROM users
366 JOIN posts posts ON posts.used_id = users.id
367 ORDER BY username, posts.title;
368
369To sort the results, use the B<order_by> attributes on a B<search> method. Content can of course be ordered by columns in the current table, or in a joined table
370
371=over
372
373=item 1. Create a Schema object representing the database you are working with:
374
375 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
376
377=item 2. Call the B<search> method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to sort data on:
378
abc32120 379# this will not collapse results (you will get users * (amount of posts || 1) as a result, sure you want to showcase this?
6c2a4396 380 my $sorted_users = $schema->resultset('User')->search(
381 { },
abc32120 382 { '+columns' => [ qw/posts.id posts.title/ ],
6c2a4396 383 join => 'posts',
384 order_by => [qw/username posts.title/],
385 }
386 );
387
388=back
389
390Here "posts" refers to the name of the L<Relationship|DBIx::Class::Relationship> between the "User" source and the "Post" source.
391
392The results will be ordered by username, then post title, ready for outputting.
393
abc32120 394Note how we have added the title of each post, this prevents us having to fire off a second query to fetch the post data to output it. The B<+columns> attribute specifies an extended set of columns to fetch, in addition to the columns of the main query table.
6c2a4396 395
396To retrieve the extra data, call the usual relationship accessor:
397
398 while( my $row = $sorted_users->next) {
399 print "user/post: ", $row->username;
400 print $_->title for $row->posts;
401 print "\n";
402 }
403
404=head2 SELECT with HAVING
405
406 SELECT users.id, username, dob
407 FROM users
408 JOIN posts posts ON posts.used_id = users.id
abc32120 409 GROUP BY users.id, username, dob
6c2a4396 410 HAVING count(posts.id) = 1
411
412To add a B<having> clause to your query, use the corresponding B<having> attribute.
413
414=over
415
416=item 1. Create a Schema object representing the database you are working with:
417
418 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
419
420=item 2. Call the B<search> method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to filter data on:
421
422 my $filtered_users = $schema->resultset('User')->search(
423 { },
abc32120 424 { 'columns' => [ qw/me.id me.username me.dob/ ],
6c2a4396 425 join => 'posts',
abc32120 426 group_by => [qw/me.id me.username me.dob/],
6c2a4396 427 having => [{ 'posts.id' => 1 }],
428 }
429 );
430
431=back
432
433Here "posts" refers to the name of the L<Relationship|DBIx::Class::Relationship> between the "User" source and the "Post" source.
434
435The results will be filtered by the HAVING clause.
436
437=head2 SELECT with DISTINCT
438
439 SELECT DISTINCT(posts.title)
440 FROM posts
441
abc32120 442To produce DISTINCT clauses, we need to use a hashref argument to the list of items passed to the B<columns> attribute.
6c2a4396 443
444=over
445
446=item 1. Create a Schema object representing the database you are working with:
447
448 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
449
abc32120 450=item 2. Call the B<search> method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to find distinct rows on:
6c2a4396 451
452 my $distinct_posts = $schema->resultset('Post')->search(
453 { },
abc32120 454 { columns => [{ 'd_title' => { distinct => 'me.title' } }],
6c2a4396 455 }
456 );
457
458=back
459
abc32120 460This can also be achieved by using the ResultSet method B<get_column>. The method returns a ResultSetColumn object based on the given column name argument, which can call SQL aggregate functions based upon the column of that data.
6c2a4396 461
abc32120 462So we can also do this, for single column DISTINCT clauses:
463
464=over
465
466=item 1. Create a Schema object representing the database you are working with:
467
468 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
469
470=item 2. Call the B<get_column> method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to find distinct rows on:
471
472 my $rs_column = $schema->resultset('Post')->get_column('title');
473
474=item 3. Call the B<func> method on the resultset column object and pass it the name of the function to apply:
475
476 my $titles = $rs_column->func('distinct');
477
478=back
479
480The result will be an arrayref of the actual values. If a ResultSet object is needed for further refinement, use B<func_rs> instead.
6c2a4396 481
482=head2 SELECT ... FOR UPDATE
483
484 SELECT users.id, users.username, users.dob
485 FROM users
486 FOR UPDATE
487
488To fetch data and lock it for updating from other transactions, use the B<for> attribute and pass it the value B<update>. This should be done inside a L<Transaction|DBIx::Class::Manual::SQLHackers::Transaction>.
489
490=over
491
492=item 1. Create a Schema object representing the database you are working with:
493
494 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
495
496=item 2. Call the B<search> method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to lock data on:
497
498 my $locked_posts = $schema->resultset('User')->search(
499 { },
500 { columns => [qw/me.id me.username me.dob/],
501 for => 'update'
502 }
503 );
504
505=back
506
507The resultset and rows will be returned as normal, and can be used to update the rows without worrying about other
508
abc32120 509=head2 SELECT with LIMIT and OFFSET
6c2a4396 510
511 SELECT users.id, users.username
512 FROM users
513 ORDER BY user.dob DESC
abc32120 514 LIMIT 10 OFFSET 11;
6c2a4396 515
abc32120 516To reduce the set of rows fetched, use the B<rows> and B<page> attributes. The value of B<page> will default to 1, which means no OFFSET will be applied.
6c2a4396 517
518=over
519
520=item 1. Create a Schema object representing the database you are working with:
521
522 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
523
524=item 2. Call the B<search> method on the resultset of the L<ResultSource|DBIx::Class::ResultSource> you wish to limit data on:
525
526 my $limited_posts = $schema->resultset('User')->search(
527 { },
528 { columns => [qw/me.id me.username/],
529 order_by => { '-desc' => ['user.dob'] },
530 rows => 10,
abc32120 531 page => 2,
6c2a4396 532 }
533 );
534
abc32120 535This will return exactly 10 row objects, sorted by descending date of birth of the users, starting at the 11th row of the sorted result.
6c2a4396 536
537=back
538