Updated according to ribasushi's review.
[dbsrgits/DBIx-Class-Manual-SQLHackers.git] / lib / DBIx / Class / Manual / SQLHackers / UPDATE.pod
CommitLineData
6c2a4396 1=head1 NAME
2
3DBIx::Class::Manual::SQLHackers::UPDATE - DBIx::Class for SQL Hackers - UPDATE
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 L<SELECT|DBIx::Class::Manual::SQLHackers::SELECT>
14
15=item 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 UPDATEing data
24
abc32120 25=head2 Single row delayed update versus direct update
6c2a4396 26
abc32120 27Individual rows may be updated via their Result object in one of two
28ways. You can create an object representing an existing database table
29row and hold it in your programmes memory, passing it around from
30function to function changing its values, before actually updating
31the contents into the database. This is a delayed update.
6c2a4396 32
33A direct update still involves fetching the existing row from the
34database, but instead of storing new column values in the Row object,
35the update method is called and passed the set of new values to store
36in the table.
37
38NOTE: Running a direct update on a row object that already has changed
39values, will *also* apply those values to the database. If values are
40changed both on the object, and in the update method arguments, the
41argument values take precedence.
42
43=head2 Updating a row in memory
44
45To create a Row object for delayed update (or other manipulations), first fetch it from the database as described in L<Simple SELECT|DBIx::Class::Manual::SQLHackers::SELECT/Simple SELECT>.
46
47=over
48
49=item 1. Create a Schema object representing the database you are working with:
50
51 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
52
53=item 2. Call the B<find> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to update the contents of:
54
55 my $fred_user = $schema->resultset('User')->find({ id => 1 });
56
abc32120 57B<$fred_user>'s contents can now be changed using the accessor
6c2a4396 58methods created by B<add_columns>, back in
59L<CREATE|DBIx::Class::Manual::SQLHackers::CREATE>. These are generally named
60after the columns in the database, so to change fred's real name, use
61the B<realname> method.
62
63=item 3. Call the B<realname> accessor method on the $fred_user object:
64
65 $fred_user->realname("John Bloggs");
66
abc32120 67
68This value has not yet changed in the database, we can make the actual
69update by calling *update*:
6c2a4396 70
71=item 4. Update the set value(s) into the database:
72
73 $fred_user->update();
74
75=back
76
abc32120 77The update method will only actually send an UPDATE statement to the
78database if one or more of the columns have changed. The internal
79tracking of which columns have been changed can be queried using
80several methods. B<is_changed> returns true (or a list of changed
81column names), if any column values have changed. B<is_column_changed>
82will return true or false for the given column name argument. The
83previous values of the columns are not stored.
84
85
6c2a4396 86=head2 Update a single row with simple values
87
88 UPDATE users
89 SET username = 'new@email.address'
90 WHERE id = 1;
91
92To update an existing row, first B<find> it using the methods shown in L<DBIx::Class::Manual::SQLHackers::SELECT/Simple SELECT, one row via the primary key> or L<DBIx::Class::Manual::SQLHackers::SELECT/Simple SELECT, one row via a unique key>, for example:
93
94=over
95
96=item 1. Create a Schema object representing the database you are working with:
97
98 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
99
100=item 2. Call the B<find> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
101
102 my $fred_user = $schema->resultset('User')->find({ id => 1 });
103
104 The Row object has an B<update> method that will change the values on
105the object, and send an UPDATE query to the database.
106
107=item 3. Call the B<update> method, passing it a hashref of new data:
108
109 $fred_user->update({ username => 'new@email.address' });
110
111=back
112
113See also: L</Direct update versus delayed update>.
114
115=head2 Update multiple rows with simple values
116
117 -- Warning, pointless example!
118 UPDATE users
119 SET dob = '2010-08-16'
120 WHERE realname LIKE 'jess%';
121
122To update a whole set of rows, or all of them, we first need to create a ResultSet object representing the query conditions that would be needed to select that same set of rows. We need to use B<search>, then we use the B<update> method on the ResultSet.
123
124=over
125
126=item 1. Create a Schema object representing the database you are working with:
127
128 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
129
130=item 2. Call the B<search> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
131
132 my $user_search = $schema->resultset('User')->search(
133 { realname => { like => 'jess%' } }
134 );
135
136=item 3. Call the B<update> method on the resultset to change the matching rows:
137
138 $user_search->update({ dob => '2010-08-16' });
139
140=back
141
142=head2 Update a row or rows using a column calculation
143
144 -- Yet another pointless example
145 UPDATE users
146 SET username = username || '.uk'
147 WHERE id = 1;
148
149=over
150
151=item 1. Create a Schema object representing the database you are working with:
152
153 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
154
155=item 2. Call the B<find> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to fetch data from:
156
157 my $fred_user = $schema->resultset('User')->find({ id => 1 });
158
159The Row object has an B<update> method that will change the values on
160the object, and send an UPDATE query to the database.
161
162=item 3. Call the B<update> method, passing it a hashref of new data:
163
abc32120 164# this won't yet work, DBIC for now mandates the [ {} => $value ] format, the simple \[ $sql, $value1, $value2 ] will start being recognized later on
165# the only documentation we currently have is this, if you can turn it into a DBIC pod-patch it will be freaking awesome
166# https://github.com/dbsrgits/dbix-class/commit/0e773352
6c2a4396 167 $fred_user->update({ username => \['username || ?', '.uk'] });
168
abc32120 169# the DBIC syntax is a tad different from te thing above (i.e. we no longer encourage 'dummy' crap)
6c2a4396 170The \[ .. ] syntax here is described in L<SQL::Abstract>
171documentation, used for passing bind parameters.
172
abc32120 173
6c2a4396 174=back
175
176=head2 Update a row based on data in other tables
177
178 -- Slightly less pointless example
179 UPDATE posts
180 SET title = user.username || title
181 JOIN users user ON user.id = posts.user_id;
182
183Joining two tables for an update is a similar sort of exercise to
184joining them for a select query and using data from both.
185
186=over
187
188=item 1. Create a Schema object representing the database you are working with:
189
190 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
191
192=item 2. Call the B<search> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to update data in, joining to the second table:
193
194 my $posts = $schema->resultset('Post')->search(
195 {},
196 { join => 'user' }
197 );
198
199 The B<join> key takes as an argument a nested structure of one or more relation names (see L<DBIx::Class::Manual::SQLHackers::CREATE>).
200
201=item 3. Call the B<update> method on the resultset to run the UPDATE statement:
202
203 $posts->update({ 'me.title' => \[ 'user.username || me.title' ] });
204
205=back
206
207=head2 Update or create a row
208
209 -- MySQL non-standardness (and another silly example)
210 INSERT INTO users ( ... )
211 VALUES ( ... )
212 ON DUPLICATE KEY UPDATE password = 'newpass';
213
214 -- OR:
215 BEGIN TRANSACTION;
216 SELECT id, username, dob, realname, password
217 FROM users
218 WHERE username = 'joebloggs';
219
220 UPDATE users
221 SET id = ?, username = ?, dob = ?, realname = ?, password = ?;
222 COMMIT;
223
224DBIx::Class does not produce the non-standard MySQL "ON DUPLICATE KEY
225UPDATE", instead it has a shortcut for combining *find* and *update*.
226
227To avoid race conditions, this should be done in a transaction.
228
229=over
230
231=item 1. Create a Schema object representing the database you are working with:
232
233 my $schema = MyDatabase::Schema->connect('dbi:SQLite:my.db');
234
235=item 2. Call the B<txn_do> method on the schema object, passing it a coderef to execute inside the transaction:
236
237 $schema->txn_do( sub {
238
239=item 3. Call the B<update_or_create> method on the resultset for the L<ResultSource|DBIx::Class::ResultSource> you wish to update data in:
240
241 $schema->resultset('User')->update_or_create(
242 {
243 username => 'joebloggs',
244 dob => '2010-09-10',
245 realname = 'Joe Bloggs'
246 },
247 {
248 key => 'uniq_username'
249 }
250 );
251
252=item 4. Close off the transaction / coderef:
253
254 } );
255
256=back
257
258A transaction is issued containing two statements, a B<SELECT> and then
259either an B<INSERT> or an B<UPDATE> depending on the results.
260
261Do not use this method if you definitely don't have either the primary
262key, or a unique index value available. The B<find> method used under
263the hood will probably not do what you expect. In this case, manually
264run a separate B<search> method call to check for existance, and then
265call B<create>.
266