From: Jess Robinson Date: Tue, 20 Dec 2011 11:32:19 +0000 (+0000) Subject: Initial Commit X-Git-Tag: v1.0~7 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=6c2a4396fbfa0868cd964f15050a67c9a36b563d;p=dbsrgits%2FDBIx-Class-Manual-SQLHackers.git Initial Commit --- 6c2a4396fbfa0868cd964f15050a67c9a36b563d diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..07ea476 --- /dev/null +++ b/.gitignore @@ -0,0 +1,15 @@ +Build +Build.bat +MANIFEST +MANIFEST.bak +META.* +MYMETA.* +Makefile +Makefile.old +README +_build/ +blib/ +inc/ +pm_to_blib +t/var/ +.*.sw? diff --git a/MANIFEST.SKIP b/MANIFEST.SKIP new file mode 100644 index 0000000..60d118c --- /dev/null +++ b/MANIFEST.SKIP @@ -0,0 +1,55 @@ +^(?!script/|examples/|lib/|inc/|t/|xt/|Makefile.PL$|README$|MANIFEST$|Changes$|META.yml$) + + +# Avoid version control files. +\bRCS\b +\bCVS\b +,v$ +\B\.svn\b +\B\.git\b +\B\.gitignore\b +\b_darcs\b + +# Avoid Makemaker generated and utility files. +\bMakefile$ +\bblib +\bMakeMaker-\d +\bpm_to_blib$ +\bblibdirs$ +^MANIFEST\.SKIP$ + +# for developers only :) +^TODO$ +^Features_09$ + +# Avoid Module::Build generated and utility files. +\bBuild$ +\b_build + +# Avoid temp and backup files. +~$ +\.tmp$ +\.old$ +\.bak$ +\..*?\.sw[po]$ +\#$ +\b\.# + +# avoid OS X finder files +\.DS_Store$ + +# Don't ship the test db +^t/var + +# Don't ship the last dist we built :) +\.tar\.gz$ + +# Skip maint stuff +^maint/ + +# Avoid patch remnants +\.orig$ +\.rej$ + +# Dont use Module::Build anymore +^Build.PL$ diff --git a/Makefile.PL b/Makefile.PL new file mode 100644 index 0000000..b6acf9d --- /dev/null +++ b/Makefile.PL @@ -0,0 +1,19 @@ +use warnings; +use strict; + +use 5.006; + +use inc::Module::Install '1.01'; + +test_requires 'Test::More' => '0.88'; # done testing +test_requires 'Test::Exception' => '0.31'; # non-segfaulting caller() + +all_from 'lib/Devel/PeekPoke.pm'; + +homepage 'http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=p5sagit/Devel-PeekPoke.git'; +resources 'IRC' => 'irc://irc.perl.org/#pp'; +resources 'license' => 'http://dev.perl.org/licenses/'; +resources 'repository' => 'git://git.shadowcat.co.uk/p5sagit/Devel-PeekPoke.git'; +resources 'bugtracker' => 'http://rt.cpan.org/NoAuth/Bugs.html?Dist=Devel-PeekPoke'; + +WriteAll; diff --git a/lib/DBIx/Class/Manual/SQLHackers/CREATE.pod b/lib/DBIx/Class/Manual/SQLHackers/CREATE.pod new file mode 100644 index 0000000..b2cf26d --- /dev/null +++ b/lib/DBIx/Class/Manual/SQLHackers/CREATE.pod @@ -0,0 +1,264 @@ +=head1 NAME + +DBIx::Class::Manual::SQLHackers::CREATE - DBIx::Class for SQL Hackers - CREATE + +=head1 Table of Contents + +=over + +=item L + +=item CREATE + +=item L + +=item L + +=item L + +=item L + +=item L + +=head1 Database structure + +To use DBIx::Class, we need to teach it about the layout of the underlying database. Several methods are supported. The built-in method involves defining your database structure as a set of perl modules. The other oft used method is to import the definitions from an existing database using the module +L. + +Once a DBIx::Class schema (set of classes describing the database) has been created, built-in methods can be used to export it to SQL using L. + +=head2 Using Loader + +Install L and decide on a name for your schema classes. + +Run the included L script. + + dbicdump -Ilib -o dump_directory=./lib \ + -o components='["InflateColumn::DateTime"]' \ + -o preserve_case=1 \ + MyApp::Schema dbi:mysql:database=foo user pass '{ quote_char => "`" }' + + +=head2 Manual Result class creation (and understanding Loader results) + +=head3 CREATE TABLE + +=head4 Standard basic table creation in SQL: + + CREATE TABLE users ( + id INTEGER AUTO_INCREMENT, + username VARCHAR(255), + dob DATE, + realname VARCHAR(255), + password VARCHAR(255) + ); + +We'll get to tables with references (foreign keys) later, here's the translation to DBIx::Class: + +The recommended version: + + package MyDatabase::Schema::Result::User; + use strict; + use warnings; + + use base 'DBIx::Class::Core'; + + __PACKAGE__->table('users'); + __PACKAGE__->add_columns( + id => { + data_type => 'integer', + is_auto_increment => 1, + }, + username => { + data_type => 'varchar', + size => 255, + }, + dob => { + data_type => 'date', + }, + realname => { + data_type => 'varchar', + size => 255, + }, + password => { + data_type => 'varchar', + size => 255, + }, + ); + __PACKAGE__->set_primary_key('id'); + __PACKAGE__->add_unique_constraint('uniq_username' => ['username']); + 1; + +The fully descriptive version is required if you want to have DBIx::Class create your CREATE TABLE sql for you later. Many DBIC components also use settings in the column info hashrefs to decide how to treat the data for those columns. + +The snappy version: + + package MyDatabase::Schema::Result::User; + use strict; + use warnings; + + use base 'DBIx::Class::Core'; + + __PACKAGE__->table('users'); + __PACKAGE__->add_columns( + id => { + data_type => 'integer', + is_auto_increment => 1, + }, + qw/username dob realname password/ + ); + __PACKAGE__->set_primary_key('id'); + + 1; + +This shows a minimal Result class to represent our "users" table. DBIx::Class itself does not use or care about the field types or lengths. However many external components exist on CPAN, and some of may use this information. + +=head4 Table creation with references: + +A relational database isn't worth much if we don't actually use references and constraints, so here is an example which constrains the B column to only contain B values from the *users* table. + + CREATE TABLE posts ( + id INTEGER AUTO_INCREMENT, + user_id INTEGER, + created_date DATETIME, + title VARCHAR(255), + post TEXT, + INDEX posts_idx_user_id (user_id), + PRIMARY KEY (id), + CONSTRAINT posts_fk_user_id FOREIGN KEY (user_id) REFERENCES users (id) + ); + +In DBIx::Class this is achieved by adding L definitions to the class: + + package MyDatabase::Schema::Result::Post; + use strict; + use warnings; + use base 'DBIx::Class::Core'; + + __PACKAGE__->table('posts'); + __PACKAGE__->add_columns( + id => { + data_type => 'integer', + is_auto_increment => 1, + }, + user_id => { + data_type => 'integer', + }, + created_date => { + data_type => 'datetime', + }, + title => { + data_type => 'varchar', + size => 255, + }, + post => { + data_type => 'text', + }, + ); + + __PACKAGE__->set_primary_key('id'); + __PACKAGE__->belongs_to('user', 'MyDatabase::Schema::Result::User', 'user_id'); + 1; + +The B relation allows us to refer to the B who authored a post as the object representing the user, rather than as just the integer tha database uses as the linking information. + +To allow access from the B object back to the posts they have written, we need to define another relationship in the User class: + + __PACKAGE__->has_many('posts', 'MyDatabase::Schema::Result::Post', 'user_id'); + +=head3 CREATE VIEW + +In SQL, a simple view that returns all users and their posts: + + CREATE VIEW userposts + AS + SELECT posts.user_id, users.username, users.dob, users.realname, posts.createddate, posts.title, posts.post + FROM users + JOIN posts ON (users.id = posts.user_id) + +In DBIx::Class this can have a Result Class of its own: + + package MyDatabase::Schema::Result::UserPosts; + + use base qw/DBIx::Class::Core/; + + __PACKAGE__->table_class('DBIx::Class::ResultSource::View'); + + __PACKAGE__->table('user_posts'); + __PACKAGE__->result_source_instance->is_virtual(1); + __PACKAGE__->result_source_instance->view_definition( + "SELECT posts.user_id, users.username, users.dob, users.realname, posts.createddate, posts.title, posts.post + FROM users + JOIN posts ON (users.id = posts.user_id)" + ); + __PACKAGE__->add_columns( + user_id => { + data_type => 'integer', + }, + username => { + data_type => 'varchar', + size => 255, + }, + dob => { + data_type => 'date', + }, + realname => { + data_type => 'varchar', + size => 255, + }, + created_date => { + data_type => 'datetime', + }, + title => { + data_type => 'varchar', + size => 255, + }, + post => { + data_type => 'text', + }, + + ); + __PACKAGE__->set_primary_key('user_id, post_id'); + +=head3 CREATE INDEX + +=head4 UNIQUE indexes + + CREATE UNIQUE INDEX username_idx ON user (username); + +To add extra unique indexes, add the B call to your Result Class. + + __PACKAGE__->add_unique_constraint('username_idx' => ['username']); + +=head3 Outputting SQL + +Once the DBIC schema has been defined, you can outout the SQL needed to create the schema in the database in one of several ways. + +=head4 Deploy directly to the database + +Create a schema object with the correct database connection, then call B on it. + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + $schema->deploy({add_drop_table => 1}); + +L has the documentation for the deploy method. + +=head4 Write out SQL files + +Create a schema object with the a database connection (any will do), and call the B on it. + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + $schema->create_ddl_dir(['SQLite', 'MySQL']); + +By default this will create an SQL file for MySQL, PostgreSQL and SQLite. More databases are supported by L if necessary. + +=head4 SQL files for upgrades (ALTER TABLE) + +DBIC can also make use of L to write out ALTER TABLE statements when the schema classes are change. + +To do this, make sure that you set a B<$VERSION> in your main Schema class, and run B on the initial version to provide a baseline. + +After the schema has changed, change the B<$VERSION> value and re-run B. + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + $schema->create_ddl_dir(\@databases, undef, '.', '0.1'); diff --git a/lib/DBIx/Class/Manual/SQLHackers/DELETE.pod b/lib/DBIx/Class/Manual/SQLHackers/DELETE.pod new file mode 100644 index 0000000..7482289 --- /dev/null +++ b/lib/DBIx/Class/Manual/SQLHackers/DELETE.pod @@ -0,0 +1,127 @@ +=head1 NAME + +DBIx::Class::Manual::SQLHackers::DELETE - DBIx::Class for SQL Hackers - DELETE + +=over + +=item L + +=item L + +=item L + +=item L + +=item L + +=item DELETE + +=item L + +=back + +=head1 DELETEing data + +=head2 Delete a single row based on the primary key + + DELETE FROM users + WHERE id = 1; + +The simplest form of delete removes a single row from a table using +the primary key value. We B the row, then call the B +method on it. B can be called on any result row object. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to delete: + + my $fred_user = $schema->resultset('User')->find({ id => 1 }); + +=item 3. Call B on the row object: + + $fred_user->delete; + +=back + +This can also be done as one statement, skipping the extra temporary +variable, if it is not needed later: + + $schema->resultset('User')->find({ id => 1 })->delete; + +In the first variant, the $fred_user row object will still contain the +last known contents of Fred's data. The *in\_storage* value will be +set to false (0), showing that the row object is not connected to a +database row. + +=head2 Delete one or more rows based on a WHERE clause + + DELETE FROM posts + WHERE created_date <= '2000-01-01'; + +Use a ResultSet to define the WHERE clause using B, then call +the B method on it directly. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to delete: + + my $old_posts = $schema->resultset('Post')->search({ + created_date => { '<=' => '2000-01-01' }, + }); + +=item 3. Call B on the row object: + + $old_posts->delete; + +=back + +Unlike the single row deletion above, the contents of the rows to be +deleted are never fetched from the database, so no record of them now +remains. + +NOTE: Calling B on a ResultSet object will not run any +overridden B methods in your Result Classes or any loaded +Components. To force these to run, call B instead: + + $old_posts->delete_all(); + +This will also issue a separate delete statement for each row to be removed. + +=head2 Cascading deletes + + DELETE FROM users + WHERE id = 1; + + DELETE FROM comments + WHERE user_id = 1; + + +Cascading deletes ensure the integrity of your data, if a User row is +removed, then any items belonging to that user (for example comments +created by the user), should also be removed. + +NOTE: This is a rather drastic action, to prevent problems in your +application, consider de-activating accounts instead of removing them! + +By default, DBIx::Class will cascade deletes for the following types +of relationships: B, B, B. That is, it +will automatically issue the above statements. See +L for how to set these up. + +Ideally, your database should cascade deletes for you, and will if references are correctly set up. In this case, you can turn off DBIx::Class' extra cascading statements: + + __PACKAGE__->has_many('posts', + 'MyDatabase::Schema::Result::Post', + 'user_id', + { cascade_delete => 0 }); + + + diff --git a/lib/DBIx/Class/Manual/SQLHackers/INSERT.pod b/lib/DBIx/Class/Manual/SQLHackers/INSERT.pod new file mode 100644 index 0000000..8686d5b --- /dev/null +++ b/lib/DBIx/Class/Manual/SQLHackers/INSERT.pod @@ -0,0 +1,173 @@ +=head1 NAME + +DBIx::Class::Manual::SQLHackers::INSERT - DBIx::Class for SQL Hackers - INSERT + +=over + +=item L + +=item L + +=item INSERT + +=item L + +=item L + +=item L + +=item L + +=back + +=head1 INSERTing data + + INSERT INTO users (id, username, dob, realname, password) + VALUES (1, 'fredbloggs', '1910-02-01', 'Fred Bloggs', 'secretpass'); + +=head2 Simple insertion, populating rows + +The B method is for inserting chunks of data to pre-populate / initialise a database with a set of known values. In void context it uses DBI's fast "insert_bulk" method. + +In scalar or list context populate is a proxy to the B method (on which more below), and returns Row objects. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method for the [Source] you wish to insert data into: + + $schema->populate('User', [ + [ qw/id username, dob, realname, password/ ], + [ 1, 'fredbloggs', '1910-02-01', + 'Fred Bloggs', 'secretpass'], + ]); + +=back + +Note that in void context you can skip passing primary key values that will be supplied by the database. However no automatic assignment of foreign key values will be made, nor will any code in your Result classes be run (eg InflateColumn components). + +=head2 Inserting with Row objects + + INSERT INTO users (username, dob, realname, password) + VALUES ('fredbloggs', '1910-02-01', 'Fred Bloggs', 'secretpass'); + +In the course of your application, you will often want to retrieve data from a user, insert it into the database, then continue to use or manipulate the resulting object. + +=over + +=item 1. Create a Schema object: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +(ideally you will always have one of these handy, no need to make many connections to the database) + +=item 2. Create a User object: + + my $newuser = $schema->resultset('User')->new({ + username => 'fredbloggs', + dob => '1910-02-01', + realname => 'Fred Bloggs', + password => 'secretpass', + }); + + $newuser is now a DBIx::Class::Row object, containing uninserted data. This can be verified by calling $newuser->in_storage, which will return false. + +=item 3. Insert the users data into the database: + + $newuser->insert(); + + $newuser has been updated to contain the auto-incremented id value in its primary key field (id). $newuser->in_storage now returns true. + +You can also shortcut these two methods if you don't need to build up the Row object before inserting: + + ## new+insert in one + my $newuser = $schema->resultset('User')->create({ + username => 'fredbloggs', + dob => '1910-02-01', + realname => 'Fred Bloggs', + password => 'secretpass', + }); + +Now *$newuser* is a Row object containing data that represents what is in the database. + +=back + +=head2 Add a post for this user + + INSERT INTO posts (user_id, created_date, title, post) + VALUES (1, '2010-03-24T09:00:00', 'First post!', 'Just testing my blog'); + +Now that we have a user, they would like to submit their first blog post. We already have the user object, from creation, or from the session when they logged in, so we can create posts using it. + +=over + +=item 1. Add a post for an existing user: + + ## Remember, create == new and insert. + my $post = $user->create_related('posts', { + created_date => '2010-03-24T09:00:00', + title => 'First post!', + post => 'Just testing my blog', + }); + +=back + +This does not require us to dig out the user's database id and pass it to the insert call for the posts table, as it is already contained in the User object. + +=head2 Insert a new user and their first post + + INSERT INTO users (username, dob, realname, password) + VALUES ('fredbloggs', '1910-02-01', 'Fred Bloggs', 'secretpass'); + + INSERT INTO posts (user_id, created_date, title, post) + VALUES (1, '2010-03-24T09:00:00', 'First post!', 'Just testing my blog'); + +This is a somewhat contrived example, as hopefully you'll want to create the user, and confirm who they are via email confirmation or similar, before allowing them to submit a blog post. Maybe it can be used for commenters and comments.. + +=over + +=item 1. Create a Schema object: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +(You still have one of these, right?) + +=item 2. Collect the User and first Post data: + + my $user_and_post = { + username => 'fredbloggs', + dob => '1910-02-01', + realname => 'Fred Bloggs', + password => 'secretpass', + posts => [ { + created_date => '2010-03-24T09:00:00', + title => 'First post!', + post => 'Just testing my blog', + } ], + }); + +=item 3. Create the User object together with the post data: + + my $newuser = $schema->resultset('User')->new( $user_and_post ); + +=item 4. Insert the user and post data into the database: + + $newuser->insert(); + +This also can be shortcut using B: + + ## new+insert in one + my $newuser = $schema->resultset('User')->create( $user_and_post ); + +=back + +=head2 Insert using a SELECT as input: + + INSERT INTO users (id, username, dob, realname, password) + SELECT (1, 'fredbloggs', '1910-02-01', 'Fred Bloggs', 'secretpass') + FROM nowhere; + +This is a TODO item for DBIC. diff --git a/lib/DBIx/Class/Manual/SQLHackers/Introduction.pod b/lib/DBIx/Class/Manual/SQLHackers/Introduction.pod new file mode 100644 index 0000000..54e4ded --- /dev/null +++ b/lib/DBIx/Class/Manual/SQLHackers/Introduction.pod @@ -0,0 +1,30 @@ +=head1 NAME + +DBIx::Class::Manual::SQLHackers::Introduction + +=head2 Introduction (Why ORMs and DBIx::Class) + +Almost every sizable Perl application these days needs a method of long term data storage. When the data needs to be easily retrieved as well as stored, we often use a database. Most databases can be comfortably accessed using SQL. Using the DBI module, and a DBD for the particular database, we can write SQL in our Perl code, and retrieve the results as arrays or hashes. + + ## Example + my $dbh = DBI->connect("dbi:SQLite:mydb.db"); + my $sth = $dbh->select("SELECT artist.id, artist.name FROM artists"); + $sth->execute; + my $results = $sth->fetchrow_arrayref({}); + + foreach my $row (@$results) { + print $row->{name}; + } + +There are several things we can do to make this code more usable, for example store the database connect string (DSN) in a configuration file so that users of the code can use different databases without editing the code. We can also write a separate method or module for creating and returning the $dbh, so that we don't create a lot of db connections unnecessarily. + +The part we can't do much about is the SQL in the code. We can move it around, put it in libraries, but it's still there, somewhere. + +Why would you not want SQL in your Perl code? For a start, it's just a string to pass to the database interpreter, there is no syntax checking at the Perl compilation level. Thus it fails late, not early. Your editor will also not syntax check what it just sees as strings of text. + +Modern Perl should also leverage OO where it can. DBI is a low level library that gets things right, but returns plain hashes and arrays, not objects. + +Perl ORMs still use DBI underneath, extending it to catch coding errors early (names of columns, SQL clauses), and to return the results as objects containing the database values, which work just like any other Perl object. + +DBIx::Class solves these issues, you write your SQL in perl instead of plain text. The syntax will be checked for you, existance of columns, catching typos and so on. It uses objects so that you can write re-usable queries, and string methods together to create complex queries. You define the database layout once, or you export it from your actual database (with ability to re-export on update). + diff --git a/lib/DBIx/Class/Manual/SQLHackers/SELECT.pod b/lib/DBIx/Class/Manual/SQLHackers/SELECT.pod new file mode 100644 index 0000000..58cbd25 --- /dev/null +++ b/lib/DBIx/Class/Manual/SQLHackers/SELECT.pod @@ -0,0 +1,528 @@ +=head1 NAME + +DBIx::Class::Manual::SQLHackers::SELECT - DBIx::Class for SQL Hackers - SELECT + +=over + +=item L + +=item L + +=item L + +=item SELECT + +=item L + +=item L + +=item L + +=back + +=head1 SELECTing data + +=head2 Fetching rows from a query + + SELECT id, username, dob, realname, password + FROM users; + +In DBIx::Class queries are represented by ResultSet objects. These are created by calling B on existing resultsets, passing new search conditions. A query is not run against the database until data is explicitly requested. + +You can either fetch all the data at once, or iterate over the results: + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. The B method returns a ResultSet representing a query with no conditions on the given B: + + my $user_resultset = $schema->resultset('User'); + +=item 3. Fetch all users as Row objects using the B method: + + my @users = $user_resultset->all(); + +=item 4. OR, fetch each user as a Row object using B: + + while( my $user = $user_resultset->next()) { + } + +=back + +=head2 Fetching column values from a Row object + +The 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 if needed). + + print $user->username; + +See the [DBIx::Class::Row]() documentation for more things you can do +with Row objects. + +=head2 Simple SELECT, one row via the primary key + + SELECT id, username, dob, realname, password + FROM users + WHERE id = 1; + +The B 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. + +If passed a condition which matches multiple rows, a warning is given. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to fetch data from: + + my $fred_user = $schema->resultset('User')->find({ id => 1 }); + +=back + +B<$fred_user> is a now Row object. + +=head2 Simple SELECT, one row via a unique key + + SELECT id, username, dob, realname, password + FROM users + WHERE username = 'fredbloggs'; + +B also works well on unique constraints, for example the username of our user. Unique constraints can be defined on Result classes using B (See L. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to fetch data from: + + my $fred_user = $schema->resultset('User')->find( + { username => 'fredbloggs' }, + { key => 'uniq_username' } + ); + +=back + +"uniq_username" is the name of a constraint defined on the User L which specifies that the username column is unique across the table. The second argument to B is a set of attributes, of which the "key" attribute defines which constraint to do a lookup on. + +=head2 Simple SELECT, with WHERE condition + + SELECT id, username, dob, realname, password + FROM users + WHERE dob = '1910-02-01'; + +To select all users born on the date '1910-02-01', we can use the B 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. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to fetch data from: + + my $dob_search = $schema->resultset('User')->search( + { dob => '1910-02-01' } + ); + +=back + +To run the query, use the B or B methods show at the beginning of this page. + +=head2 SELECT with different WHERE conditions + +Below are shown some common SQL where conditions. The syntax for these is parsed by a module called L which DBIx::Class uses. They can all be passed to the B method as conditions. + + SELECT id, username, dob, realname, password + FROM users + WHERE username LIKE 'fred%'; + + my $name_search = $schema->resultset('User')->search( + { username => { '-like' => 'fred%' } } + ); + + SELECT id, username, dob, realname, password + FROM users + WHERE dob BETWEEN '1910-01-01' AND '1910-12-31'; + + my $year_dob_search = $schema->resultset('User')->search( + { dob => { '-between' => ['1910-01-01', '1910-12-31'] } } + ); + + SELECT id, username, dob, realname, password + FROM users + WHERE dob IN ('1910-02-01', '1910-02-02'); + + my $feb_dob_search = $schema->resultset('User')->search( + { dob => { '-in' => ['1910-02-01', '1910-02-02'] } } + ); + + SELECT id, username, dob, realname, password + FROM users + WHERE dob >= 1911-01-01; + + my $next_year_dob = $schema->resultset('User')->search( + { dob => { '>=', '1911-01-01' } } + ); + + +=head2 SELECT with WHERE condition on JOINed table + + SELECT posts.id, created_date, title, post + FROM posts + JOIN users user ON user.id = posts.user_id + WHERE user.username = 'fredbloggs'; + +The second argument to B is a hashref of attributes to apply to the query. One of them is B, which is used to connect to other tables using the relationships defined in the Result classes. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to fetch data from: + + my $freds_posts = $schema->resultset('Post')->search( + { 'user.username' => 'fredbloggs' }, + { join => 'user' } + ); + +=back + +Note that the string "user", used twice here, refers to the B of the L between the "Post" source and the "User" source. All dealings with related tables are refered to by relationship names, not table names. + +To run the query, use the B or B methods show at the beginning of this page. + +=head2 SELECT with fewer columns + + SELECT id, title + FROM posts + +There'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. + +B will always pull all the columns for the found row, so use the *search* method for this. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to fetch data from: + + my $post_titles = $schema->resultset('Post')->search( + { }, + { columns => [qw/id title/] } + ); + +=back + +Note that accessors for other columns not fetched will return B. To discover whether a columns data has been loaded or not, use the B method. + + +=head2 SELECT with aggregates + + SELECT COUNT(*) + FROM users; + +To find out how many users exist. This simple one can be achieved with a built-in method, B. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the *count* method on the resultset for the [Source] you wish to fetch data from: + + my $posts_count = $schema->resultset('Post')->count(); + +=back + +The result is not an object, just a number. + + SELECT SUM(amount) + FROM prices; + +A 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 method, by calling B. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to fetch data from, then the B method: + + my $sum_prices = $schema->resultset('Price')->get_column('amount') + ->sum(); + +=back + +The result is just a number. + +The alternate way uses the B method and is easier to build further refinements into. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset for the L you wish to fetch data from: + + my $sum_prices_rs = $schema->resultset('Price')->search( + { }, + { select => [ { SUM => 'amount'} ], + as => [ 'sum_amount' ] } + ); + +=back + +The result is a resultset. To fetch the one-row result, call B or B. 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. + + print $sum_prices_rs->single->get_column('sum_amount'); + +=head2 SELECT from JOINed tables + + SELECT users.id, username, posts.id, posts.title + FROM users + JOIN posts posts ON posts.used_id = users.id + +To select data from other tables, use the B attribute to name the table relationships to create a JOIN clause to. + +=over + +=item 1. Create a Schema object representing the database you are working with: + + my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db'); + +=item 2. Call the B method on the resultset of the L you wish to group data on: + + my $posts_count_per_user = $schema->resultset('User')->search( + { }, + { select => [ qw/id username posts.id posts.title/ ], + as => [ qw/id username posts.id posts.title/ ], + join => 'posts', + } + ); + +=back + +Here "posts" refers to the name of the L between the "User" source and the "Post" source. + +To retrieve the extra data, call the usual relationship accessor: + + while( my $row = $sorted_users->next) { + print "user/post: ", $row->username; + print $_->title for $row->posts; + print "\n"; + } + + +=head2 SELECT with GROUP BY + + SELECT users.id, username, COUNT(posts.id) + FROM users + JOIN posts posts ON posts.used_id = users.id + GROUP BY users.id, username; + +To group your results, use the B attribute on a B method. We also use the B and then +either an B or an B depending on the results. + +Do not use this method if you definitely don't have either the primary +key, or a unique index value available. The B method used under +the hood will probably not do what you expect. In this case, manually +run a separate B method call to check for existance, and then +call B. +