File: Cookbook.pod

package info (click to toggle)
libdbix-class-perl 0.08010-2
  • links: PTS, VCS
  • area: main
  • in suites: lenny
  • size: 2,052 kB
  • ctags: 1,064
  • sloc: perl: 10,536; sql: 225; makefile: 45
file content (1435 lines) | stat: -rwxr-xr-x 42,334 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
=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<DBIx::Class> 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<page> 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<Data::Page> object for the
resultset (suitable for use in e.g. a template) using the C<pager> 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<WHERE> 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<WHERE> clause:

  WHERE ( artist LIKE '%Smashing Pumpkins%' AND title = 'Siamese Dream' )
    OR artist = 'Starchildren'

For more information on generating complex queries, see
L<SQL::Abstract/WHERE CLAUSES>.

=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<DBIx::Class::ResultSet>. 
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<SQL::Abstract>).

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( \<<SQL );
  ( SELECT u.* FROM user u 
  INNER JOIN user_friends f ON u.id = f.user_id 
  WHERE f.friend_user_id = ?
  UNION 
  SELECT u.* FROM user u 
  INNER JOIN user_friends f ON u.id = f.friend_user_id 
  WHERE f.user_id = ? )
  SQL 

  # Finally, register your new ResultSource with your Schema
  My::Schema->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<DBIx::Class::ResultSet>.

=head2 Using specific columns

When you only want specific columns from a table, you can use
C<columns> 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<select> and C<as>, see below. C<columns>
cannot be used together with C<select> and C<as>.

=head2 Using database functions or stored procedures

The combination of C<select> and C<as> can be used to return the result of a
database function or stored procedure as a column value. You use C<select> to
specify the source for your column value (e.g. a column name, function, or
stored procedure name). You then use C<as> 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<DBIx::Class::ResultSet/ATTRIBUTES>).  If your alias exists as a
column in your base class (i.e. it was added with C<add_columns>), you
just access it as normal. Our C<Artist> class has a C<name> column, so
we just use the C<name> 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<get_column> accessor:

  my $name_length = $artist->get_column('name_length');

If you don't like using C<get_column>, 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 :-)
    }
  );

  my $count = $rs->next->get_column('count');

=head2 SELECT COUNT(DISTINCT colname)

  my $rs = $schema->resultset('Foo')->search(
    {},
    {
      select => [
        { count => { distinct => 'colname' } }
      ],
      as => [ 'count' ]
    }
  );

=head2 Grouping results

L<DBIx::Class> supports C<GROUP BY> 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<DBIx::Class::ResultSet/ATTRIBUTES> 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<DBIx::Class::ResultSet> 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:

  __PACKAGE__->resultset_class('My::DBIC::ResultSet::CD');

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<DBIx::Class> 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<where>
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<where> and
C<bind> 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<join> 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<order_by> 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<join> 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<cd> and C<artist> tables
in our main query, but we have only returned data from the C<cd> table. To get
the artist name for any of the CD objects returned, L<DBIx::Class> 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<DBIx::Class> has a C<prefetch> 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<DBIx::Class> has now prefetched all matching data from the C<artist> table,
so no additional SQL statements are executed. You now have a much more
efficient query.

Note that as of L<DBIx::Class> 0.05999_01, C<prefetch> I<can> be used with
C<has_many> relationships.

Also note that C<prefetch> 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<Artist> objects who have C<CD>s whose C<LinerNotes>
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<prefetch> 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<cd> and C<artist> 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<overload>
module.

To make an object stringify itself as a single column, use something
like this (replace C<foo> 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<Product> and C<Category>. The table
specifications are:

  Product(id, Description, category)
  Category(id, Description)

C<category> 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<find_or_new> instead, then check C<in_storage>:

  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<DBIx::Class> 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<DBIx::Class::Row>) 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<inflate_result> method within the User proxy-class
gives us the effect we want.  This method is called by
L<DBIx::Class::ResultSet> 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<Schema Definition> 
 
    package DB::Schema; 
     
    use base qw/DBIx::Class::Schema/; 
 
    __PACKAGE__->load_classes(qw/User/); 
 
 
B<Proxy-Class definitions> 
 
    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 File> 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<DBIx::Class::ResultClass::HashRefInflator>.
  
 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<HashRefInflator|DBIx::Class::ResultClass::HashRefInflator> 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<select> attribute of C<search()> to force ordering).

=head1 RESULTSET OPERATIONS

=head2 Getting Schema from a ResultSet

To get the schema object from a result set, do the following:

 $rs->result_source->schema

=head2 Getting Columns Of Data

AKA Aggregating Data

If you want to find the sum of a particular column there are several
ways, the obvious one is to use search:

  my $rs = $schema->resultset('Items')->search(
    {},
    { 
       select => [ { sum => 'Cost' } ],
       as     => [ 'total_cost' ], # remember this 'as' is for DBIx::Class::ResultSet not SQL
    }
  );
  my $tc = $rs->first->get_column('total_cost');

Or, you can use the L<DBIx::Class::ResultSetColumn>, which gets
returned when you ask the C<ResultSet> for a column using
C<get_column>:

  my $cost = $schema->resultset('Items')->get_column('Cost');
  my $tc = $cost->sum;

With this you can also do:

  my $minvalue = $cost->min;
  my $maxvalue = $cost->max;

Or just iterate through the values of this column only:

  while ( my $c = $cost->next ) {
    print $c;
  }

  foreach my $c ($cost->all) {
    print $c;
  }

C<ResultSetColumn> only has a limited number of built-in functions, if
you need one that it doesn't have, then you can use the C<func> method
instead:

  my $avg = $cost->func('AVERAGE');

This will cause the following SQL statement to be run:

  SELECT AVERAGE(Cost) FROM Items me

Which will of course only work if your database supports this function.
See L<DBIx::Class::ResultSetColumn> for more documentation.

=head1 USING RELATIONSHIPS

=head2 Create a new row in a related table

  my $author = $book->create_related('author', { name => 'Fred'});

=head2 Search in a related table

Only searches for books named 'Titanic' by the author in $author.

  my $books_rs = $author->search_related('books', { name => 'Titanic' });

=head2 Delete data in a related table

Deletes only the book named Titanic by the author in $author.

  $author->delete_related('books', { name => 'Titanic' });

=head2 Ordering a relationship result set

If you always want a relation to be ordered, you can specify this when you 
create the relationship.

To order C<< $book->pages >> by descending page_number, create the relation
as follows:

  __PACKAGE__->has_many('pages' => 'Page', 'book', { order_by => \'page_number DESC'} );

=head2 Many-to-many relationships

This is straightforward using L<ManyToMany|DBIx::Class::Relationship/many_to_many>:

  package My::User;
  use base 'DBIx::Class';
  __PACKAGE__->load_components('Core');
  __PACKAGE__->table('user');
  __PACKAGE__->add_columns(qw/id name/);
  __PACKAGE__->set_primary_key('id');
  __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'user');
  __PACKAGE__->many_to_many('addresses' => 'user_address', 'address');

  package My::UserAddress;
  use base 'DBIx::Class';
  __PACKAGE__->load_components('Core');
  __PACKAGE__->table('user_address');
  __PACKAGE__->add_columns(qw/user address/);
  __PACKAGE__->set_primary_key(qw/user address/);
  __PACKAGE__->belongs_to('user' => 'My::User');
  __PACKAGE__->belongs_to('address' => 'My::Address');

  package My::Address;
  use base 'DBIx::Class';
  __PACKAGE__->load_components('Core');
  __PACKAGE__->table('address');
  __PACKAGE__->add_columns(qw/id street town area_code country/);
  __PACKAGE__->set_primary_key('id');
  __PACKAGE__->has_many('user_address' => 'My::UserAddress', 'address');
  __PACKAGE__->many_to_many('users' => 'user_address', 'user');

  $rs = $user->addresses(); # get all addresses for a user
  $rs = $address->users(); # get all users for an address

=head1 TRANSACTIONS

As of version 0.04001, there is improved transaction support in
L<DBIx::Class::Storage> and L<DBIx::Class::Schema>.  Here is an
example of the recommended way to use it:

  my $genus = $schema->resultset('Genus')->find(12);

  my $coderef2 = sub {
    $genus->extinct(1);
    $genus->update;
  };

  my $coderef1 = sub {
    $genus->add_to_species({ name => 'troglodyte' });
    $genus->wings(2);
    $genus->update;
    $schema->txn_do($coderef2); # Can have a nested transaction. Only the outer will actualy commit
    return $genus->species;
  };

  my $rs;
  eval {
    $rs = $schema->txn_do($coderef1);
  };

  if ($@) {                             # Transaction failed
    die "the sky is falling!"           #
      if ($@ =~ /Rollback failed/);     # Rollback failed

    deal_with_failed_transaction();
  }

Nested transactions will work as expected. That is, only the outermost
transaction will actually issue a commit to the $dbh, and a rollback
at any level of any transaction will cause the entire nested
transaction to fail. Support for savepoints and for true nested
transactions (for databases that support them) will hopefully be added
in the future.

=head1 SQL 

=head2 Creating Schemas From An Existing Database

L<DBIx::Class::Schema::Loader> will connect to a database and create a 
L<DBIx::Class::Schema> and associated sources by examining the database.

The recommend way of achieving this is to use the 
L<make_schema_at|DBIx::Class::Schema::Loader/make_schema_at> method:

  perl -MDBIx::Class::Schema::Loader=make_schema_at,dump_to_dir:./lib \
    -e 'make_schema_at("My::Schema", { debug => 1 }, [ "dbi:Pg:dbname=foo","postgres" ])'

This will create a tree of files rooted at C<./lib/My/Schema/> containing
source definitions for all the tables found in the C<foo> database.

=head2 Creating DDL SQL

The following functionality requires you to have L<SQL::Translator>
(also known as "SQL Fairy") installed.

To create a set of database-specific .sql files for the above schema:

 my $schema = My::Schema->connect($dsn);
 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
                        '0.1',
                        './dbscriptdir/'
                        );

By default this will create schema files in the current directory, for
MySQL, SQLite and PostgreSQL, using the $VERSION from your Schema.pm.

To create a new database using the schema:

 my $schema = My::Schema->connect($dsn);
 $schema->deploy({ add_drop_tables => 1});

To import created .sql files using the mysql client:

  mysql -h "host" -D "database" -u "user" -p < My_Schema_1.0_MySQL.sql

To create C<ALTER TABLE> conversion scripts to update a database to a
newer version of your schema at a later point, first set a new
C<$VERSION> in your Schema file, then:

 my $schema = My::Schema->connect($dsn);
 $schema->create_ddl_dir(['MySQL', 'SQLite', 'PostgreSQL'],
                         '0.2',
                         '/dbscriptdir/',
                         '0.1'
                         );

This will produce new database-specific .sql files for the new version
of the schema, plus scripts to convert from version 0.1 to 0.2. This
requires that the files for 0.1 as created above are available in the
given directory to diff against.

=head2 Select from dual

Dummy tables are needed by some databases to allow calling functions
or expressions that aren't based on table content, for examples of how
this applies to various database types, see:
L<http://troels.arvin.dk/db/rdbms/#other-dummy_table>.

Note: If you're using Oracles dual table don't B<ever> do anything
other than a select, if you CRUD on your dual table you *will* break
your database.

Make a table class as you would for any other table
                                                                               
  package MyAppDB::Dual;
  use strict;
  use warnings;
  use base 'DBIx::Class';
  __PACKAGE__->load_components("Core");
  __PACKAGE__->table("Dual");
  __PACKAGE__->add_columns(
    "dummy",
    { data_type => "VARCHAR2", is_nullable => 0, size => 1 },
  );
 
Once you've loaded your table class select from it using C<select>
and C<as> instead of C<columns>
 
  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<as> instead of 'now', or C<add_columns> to
your Dual class for whatever you wanted to select from dual, but that's just
silly, instead use C<get_column>
 
  while (my $dual = $rs->next) {
    print $dual->get_column('now')."\n";
  }
 
Or use C<cursor>
 
  my $cursor = $rs->cursor;
  while (my @vals = $cursor->next) {
    print $vals[0]."\n";
  }
 
Or use L<DBIx::Class::ResultClass::HashRefInflator>
 
  $rs->result_class('DBIx::Class::ResultClass::HashRefInflator');
  while ( my $dual = $rs->next ) {
    print $dual->{now}."\n";
  }
 
Here are some example C<select> conditions to illustrate the different syntax
you could use for doing stuff like 
C<oracles.heavily(nested(functions_can('take', 'lots'), OF), 'args')>
 
  # get a sequence value
  select => [ 'A_SEQ.nextval' ],
 
  # get create table sql
  select => [ { 'dbms_metadata.get_ddl' => [ "'TABLE'", "'ARTIST'" ]} ],
 
  # get a random num between 0 and 100
  select => [ { "trunc" => [ { "dbms_random.value" => [0,100] } ]} ],
 
  # what year is it?
  select => [ { 'extract' => [ \'year from sysdate' ] } ],
 
  # do some math
  select => [ {'round' => [{'cos' => [ \'180 * 3.14159265359/180' ]}]}],
 
  # which day of the week were you born on?
  select => [{'to_char' => [{'to_date' => [ "'25-DEC-1980'", "'dd-mon-yyyy'" ]}, "'day'"]}],
 
  # select 16 rows from dual
  select   => [ "'hello'" ],
  as       => [ 'world' ],
  group_by => [ 'cube( 1, 2, 3, 4 )' ],
 
 

=head2 Adding Indexes And Functions To Your SQL

Often you will want indexes on columns on your table to speed up searching. To
do this, create a method called C<sqlt_deploy_hook> in the relevant source 
class:

 package My::Schema::Artist;

 __PACKAGE__->table('artist');
 __PACKAGE__->add_columns(id => { ... }, name => { ... })

 sub sqlt_deploy_hook {
   my ($self, $sqlt_table) = @_;

   $sqlt_table->add_index(name => 'idx_name', fields => ['name']);
 }

 1;

Sometimes you might want to change the index depending on the type of the 
database for which SQL is being generated:

  my ($db_type = $sqlt_table->schema->translator->producer_type)
    =~ s/^SQL::Translator::Producer:://;

You can also add hooks to the schema level to stop certain tables being 
created:

 package My::Schema;

 ...

 sub sqlt_deploy_hook {
   my ($self, $sqlt_schema) = @_;

   $sqlt_schema->drop_table('table_name');
 }

You could also add views or procedures to the output using 
L<SQL::Translator::Schema/add_view> or 
L<SQL::Translator::Schema/add_procedure>.

=head2 Schema versioning

The following example shows simplistically how you might use DBIx::Class to
deploy versioned schemas to your customers. The basic process is as follows:

=over 4

=item 1.

Create a DBIx::Class schema

=item 2.

Save the schema

=item 3.

Deploy to customers

=item 4.

Modify schema to change functionality

=item 5.

Deploy update to customers

=back

B<Create a DBIx::Class schema>

This can either be done manually, or generated from an existing database as
described under L</Creating Schemas From An Existing Database>

B<Save the schema>

Call L<DBIx::Class::Schema/create_ddl_dir> as above under L</Creating DDL SQL>.

B<Deploy to customers>

There are several ways you could deploy your schema. These are probably
beyond the scope of this recipe, but might include:

=over 4

=item 1.

Require customer to apply manually using their RDBMS.

=item 2.

Package along with your app, making database dump/schema update/tests
all part of your install.

=back

B<Modify the schema to change functionality>

As your application evolves, it may be necessary to modify your schema
to change functionality. Once the changes are made to your schema in
DBIx::Class, export the modified schema and the conversion scripts as
in L</Creating DDL SQL>.

B<Deploy update to customers>

Add the L<DBIx::Class::Schema::Versioned> schema component to your
Schema class. This will add a new table to your database called
C<SchemaVersions> which will keep track of which version is installed
and warn if the user trys to run a newer schema version than the
database thinks it has.

Alternatively, you can send the conversion sql scripts to your
customers as above.

=head2 Setting quoting for the generated SQL. 

If the database contains column names with spaces and/or reserved words, they
need to be quoted in the SQL queries. This is done using:

 __PACKAGE__->storage->sql_maker->quote_char([ qw/[ ]/] );
 __PACKAGE__->storage->sql_maker->name_sep('.');

The first sets the quote characters. Either a pair of matching
brackets, or a C<"> or C<'>:
  
 __PACKAGE__->storage->sql_maker->quote_char('"');

Check the documentation of your database for the correct quote
characters to use. C<name_sep> needs to be set to allow the SQL
generator to put the quotes the correct place.

In most cases you should set these as part of the arguments passed to 
L<DBIx::Class::Schema/conect>:

 my $schema = My::Schema->connect(
  'dbi:mysql:my_db',
  'db_user',
  'db_password',
  {
    quote_char => '"',
    name_sep   => '.'
  }
 )

=head2 Setting limit dialect for SQL::Abstract::Limit

In some cases, SQL::Abstract::Limit cannot determine the dialect of
the remote SQL server by looking at the database handle. This is a
common problem when using the DBD::JDBC, since the DBD-driver only
know that in has a Java-driver available, not which JDBC driver the
Java component has loaded.  This specifically sets the limit_dialect
to Microsoft SQL-server (See more names in SQL::Abstract::Limit
-documentation.

  __PACKAGE__->storage->sql_maker->limit_dialect('mssql');

The JDBC bridge is one way of getting access to a MSSQL server from a platform
that Microsoft doesn't deliver native client libraries for. (e.g. Linux)

The limit dialect can also be set at connect time by specifying a 
C<limit_dialect> key in the final hash as shown above.

=head1 BOOTSTRAPPING/MIGRATING 

=head2 Easy migration from class-based to schema-based setup

You want to start using the schema-based approach to L<DBIx::Class>
(see L<SchemaIntro.pod>), but have an established class-based setup with lots
of existing classes that you don't want to move by hand. Try this nifty script
instead:

  use MyDB;
  use SQL::Translator;
  
  my $schema = MyDB->schema_instance;
  
  my $translator           =  SQL::Translator->new( 
      debug                => $debug          ||  0,
      trace                => $trace          ||  0,
      no_comments          => $no_comments    ||  0,
      show_warnings        => $show_warnings  ||  0,
      add_drop_table       => $add_drop_table ||  0,
      validate             => $validate       ||  0,
      parser_args          => {
         'DBIx::Schema'    => $schema,
                              },
      producer_args   => {
          'prefix'         => 'My::Schema',
                         },
  );
  
  $translator->parser('SQL::Translator::Parser::DBIx::Class');
  $translator->producer('SQL::Translator::Producer::DBIx::Class::File');
  
  my $output = $translator->translate(@args) or die
          "Error: " . $translator->error;
  
  print $output;

You could use L<Module::Find> to search for all subclasses in the MyDB::*
namespace, which is currently left as an exercise for the reader.

=head1 OVERLOADING METHODS

L<DBIx::Class> uses the L<Class::C3> package, which provides for redispatch of
method calls, useful for things like default values and triggers. You have to
use calls to C<next::method> to overload methods. More information on using
L<Class::C3> with L<DBIx::Class> can be found in
L<DBIx::Class::Manual::Component>.

=head2 Setting default values for a row

It's as simple as overriding the C<new> method.  Note the use of
C<next::method>.

  sub new {
    my ( $class, $attrs ) = @_;

    $attrs->{foo} = 'bar' unless defined $attrs->{foo};

    my $new = $class->next::method($attrs);

    return $new;
  }

For more information about C<next::method>, look in the L<Class::C3> 
documentation. See also L<DBIx::Class::Manual::Component> for more
ways to write your own base classes to do this.

People looking for ways to do "triggers" with DBIx::Class are probably
just looking for this. 

=head2 Changing one field whenever another changes

For example, say that you have three columns, C<id>, C<number>, and 
C<squared>.  You would like to make changes to C<number> and have
C<squared> be automagically set to the value of C<number> squared.
You can accomplish this by overriding C<store_column>:

  sub store_column {
    my ( $self, $name, $value ) = @_;
    if ($name eq 'number') {
      $self->squared($value * $value);
    }
    $self->next::method($name, $value);
  }

Note that the hard work is done by the call to C<next::method>, which
redispatches your call to store_column in the superclass(es).

=head2 Automatically creating related objects

You might have a class C<Artist> which has many C<CD>s.  Further, if you
want to create a C<CD> object every time you insert an C<Artist> object.
You can accomplish this by overriding C<insert> on your objects:

  sub insert {
    my ( $self, @args ) = @_;
    $self->next::method(@args);
    $self->cds->new({})->fill_from_artist($self)->insert;
    return $self;
  }

where C<fill_from_artist> is a method you specify in C<CD> which sets
values in C<CD> based on the data in the C<Artist> object you pass in.

=head2 Wrapping/overloading a column accessor

B<Problem:>

Say you have a table "Camera" and want to associate a description
with each camera. For most cameras, you'll be able to generate the description from
the other columns. However, in a few special cases you may want to associate a
custom description with a camera.

B<Solution:>

In your database schema, define a description field in the "Camera" table that
can contain text and null values.

In DBIC, we'll overload the column accessor to provide a sane default if no
custom description is defined. The accessor will either return or generate the
description, depending on whether the field is null or not.

First, in your "Camera" schema class, define the description field as follows:

  __PACKAGE__->add_columns(description => { accessor => '_description' });

Next, we'll define the accessor-wrapper subroutine:

  sub description {
      my $self = shift;

      # If there is an update to the column, we'll let the original accessor
      # deal with it.
      return $self->_description(@_) if @_;

      # Fetch the column value.
      my $description = $self->_description;

      # If there's something in the description field, then just return that.
      return $description if defined $description && length $descripton;

      # Otherwise, generate a description.
      return $self->generate_description;
  }

=head1 DEBUGGING AND PROFILING

=head2 DBIx::Class objects with Data::Dumper

L<Data::Dumper> can be a very useful tool for debugging, but sometimes it can
be hard to find the pertinent data in all the data it can generate.
Specifically, if one naively tries to use it like so,

  use Data::Dumper;

  my $cd = $schema->resultset('CD')->find(1);
  print Dumper($cd);

several pages worth of data from the CD object's schema and result source will
be dumped to the screen. Since usually one is only interested in a few column
values of the object, this is not very helpful.

Luckily, it is possible to modify the data before L<Data::Dumper> outputs
it. Simply define a hook that L<Data::Dumper> will call on the object before
dumping it. For example,

  package My::DB::CD;

  sub _dumper_hook {
    $_[0] = bless {
      %{ $_[0] },
      result_source => undef,
    }, ref($_[0]);
  }

  [...]

  use Data::Dumper;

  local $Data::Dumper::Freezer = '_dumper_hook';

  my $cd = $schema->resultset('CD')->find(1);
  print Dumper($cd);
         # dumps $cd without its ResultSource

If the structure of your schema is such that there is a common base class for
all your table classes, simply put a method similar to C<_dumper_hook> in the
base class and set C<$Data::Dumper::Freezer> to its name and L<Data::Dumper>
will automagically clean up your data before printing it. See
L<Data::Dumper/EXAMPLES> for more information.

=head2 Profiling

When you enable L<DBIx::Class::Storage>'s debugging it prints the SQL
executed as well as notifications of query completion and transaction
begin/commit.  If you'd like to profile the SQL you can subclass the
L<DBIx::Class::Storage::Statistics> class and write your own profiling
mechanism:

  package My::Profiler;
  use strict;

  use base 'DBIx::Class::Storage::Statistics';

  use Time::HiRes qw(time);

  my $start;

  sub query_start {
    my $self = shift();
    my $sql = shift();
    my $params = @_;

    $self->print("Executing $sql: ".join(', ', @params)."\n");
    $start = time();
  }

  sub query_end {
    my $self = shift();
    my $sql = shift();
    my @params = @_;

    my $elapsed = sprintf("%0.4f", time() - $start);
    $self->print("Execution took $elapsed seconds.\n");
    $start = undef;
  }

  1;

You can then install that class as the debugging object:

  __PACKAGE__->storage->debugobj(new My::Profiler());
  __PACKAGE__->storage->debug(1);

A more complicated example might involve storing each execution of SQL in an
array:

  sub query_end {
    my $self = shift();
    my $sql = shift();
    my @params = @_;

    my $elapsed = time() - $start;
    push(@{ $calls{$sql} }, {
        params => \@params,
        elapsed => $elapsed
    });
  }

You could then create average, high and low execution times for an SQL
statement and dig down to see if certain parameters cause aberrant behavior.
You might want to check out L<DBIx::Class::QueryLog> as well.


=cut