In this post, we’re going to take a look at the U in CRUD: Update.
We use the ruby-oci8 driver to update some data in the database tables, using the connection object created in the Initial Setup section of the first post in this series.
PLEASE REVIEW ALL EXAMPLE CODE AND ONLY RUN IT IF YOU ARE SURE IT WILL NOT CAUSE ANY PROBLEMS WITH YOUR SYSTEM.
Helper Function
My helper function get_all_rows() encapsulates a select statement used to verify that the updates worked. The select functionality is covered in the R part of this series, so I won’t go into the details here.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 |
def get_all_rows (label, data_type = 'people') connectString = ENV['DB_CONNECT'] con = OCI8.new(connectString) # Query all rows statement = 'select id, name, age, notes from lcs_people order by id'; if data_type == 'pets' statement = 'select id, name, owner, type from lcs_pets order by owner, id' end cursor = con.parse(statement) cursor.exec printf " %s:\n", label cursor.fetch() {|row| if data_type == 'people' printf " Id: %d, Name: %s, Age: %d, Notes: %s\n", row[0], row[1], row[2], row[3] else printf " Id: %d, Name: %s, Owner: %d, Type: %s\n", row[0], row[1], row[2], row[3] end } printf "\n" end |
Add this function to the top of your file.
Resetting the data
To keep the examples clean and precise, I will reset the data at times.
Create a new file called reset_data.rb with the following code and then run it whenever you would like to reset the data. (Notice this version adds pet data not included in other sections.)
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 |
# Query all rows require 'oci8' connectString = ENV['DB_CONNECT'] con = OCI8.new(connectString) # Delete rows cursor = con.parse("delete from lcs_pets") cursor.exec # Reset Identity Coulmn cursor = con.parse("alter table lcs_pets modify id generated BY DEFAULT as identity (START WITH 8)") cursor.exec # Delete rows cursor = con.parse("delete from lcs_people") cursor.exec # Reset Identity Coulmn cursor = con.parse("alter table lcs_people modify id generated BY DEFAULT as identity (START WITH 3)") cursor.exec # Insert default people rows cursor = con.parse("INSERT INTO lcs_people(id, name, age, notes) VALUES (:id, :name, :age, :notes)") cursor.max_array_size = 2 cursor.bind_param_array(:id, [1, 2]) cursor.bind_param_array(:name, ["Bob", "Kim"]) cursor.bind_param_array(:age, [35, 27]) cursor.bind_param_array(:notes, ["I like dogs", "I like birds"]) people_row_count = cursor.exec_array printf " %d people rows inserted\n", people_row_count # Insert default pet rows cursor = con.parse("INSERT INTO lcs_pets(id, name, owner, type) VALUES (:id, :name, :owner, :type)") cursor.max_array_size = 7 cursor.bind_param_array(:id, [1, 2, 3, 4, 5, 6, 7]) cursor.bind_param_array(:name, ["Duke", "Pepe", "Princess", "Polly", "Rollo", "Buster", "Fido"]) cursor.bind_param_array(:owner, [1, 2, 1, 1, 1, 1, 1]) cursor.bind_param_array(:type, ["dog", "bird", "snake", "bird", "horse", "dog", "cat"]) pet_row_count = cursor.exec_array printf " %d pet rows inserted\n", pet_row_count con.commit |
Boilerplate template
The template we will be using is:
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 |
require 'oci8' connectString = ENV['DB_CONNECT'] def get_all_rows (label, data_type = 'people') connectString = ENV['DB_CONNECT'] con = OCI8.new(connectString) # Query all rows statement = 'select id, name, age, notes from lcs_people order by id'; if data_type == 'pets' statement = 'select id, name, owner, type from lcs_pets order by owner, id' end cursor = con.parse(statement) cursor.exec printf " %s:\n", label cursor.fetch() {|row| if data_type == 'people' printf " Id: %d, Name: %s, Age: %d, Notes: %s\n", row[0], row[1], row[2], row[3] else printf " Id: %d, Name: %s, Owner: %d, Type: %s\n", row[0], row[1], row[2], row[3] end } printf "\n" end con = OCI8.new(connectString) get_all_rows('Original Data') # Your code here get_all_rows('New Data') |
For each exercise, replace the “# Your code here” line with your code.
Simple update
We will perform a simple update that modifies a single record in the lcs_people table. These are the steps performed in the code snippet below.
- Prepare a SQL UPDATE statement, changing age to 31 for the record with an id of 1.
- Parse the statement to create a cursor.
- Bind the age and id values. (See the R part of this series for an explanation of bind variables.)
- Execute the statement.
- Commit the transaction.
1 2 3 4 5 6 |
statement = "update lcs_people set age = :age where id = :id" cursor = con.parse(statement) cursor.bind_param(:age,31) cursor.bind_param(:id,1) cursor.exec con.commit |

1 2 3 4 5 6 7 8 |
Example: ruby update1.rb Original Data: Id: 1, Name: Bob, Age: 35, Notes: I like dogs Id: 2, Name: Kim, Age: 27, Notes: I like birds New Data: Id: 1, Name: Bob, Age: 31, Notes: I like dogs Id: 2, Name: Kim, Age: 27, Notes: I like birds |
Extra Fun 1
Update Bob’s notes to ‘I like cats’.
Your results should be:
1 2 3 4 5 6 7 |
Original Data: Id: 1, Name: Bob, Age: 31, Notes: I like dogs Id: 2, Name: Kim, Age: 27, Notes: I like birds New Data: Id: 1, Name: Bob, Age: 31, Notes: I like cats Id: 2, Name: Kim, Age: 27, Notes: I like birds |
Reset the data
Now is a good time to run reset_data.rb.
Boilerplate change
Change the boilerplate get_all_rows statements to get pet data.
1 2 3 4 5 |
get_all_rows('Original Data', 'pets'); # Your code here get_all_rows('New Data', 'pets'); |
Make sure your where clause is specific
In the above example, notice that we used the id column in our where clause. For our data set, id is the primary key. You do not always have to use a primary key, but you should make sure you only update the rows you intend to.
Next, let’s look at updating multiple rows. We’ll have Bob give his dog Duke to Kim.
- Prepare a SQL UPDATE statement, changing owner to 2 for the record with an owner of 1 and a type of ‘dog’.
- Parse the statement to create a cursor.
- Bind the newOwner, oldOwner and type values.
- Execute the statement.
- Commit the transaction.
1 2 3 4 5 6 7 |
statement = "update lcs_pets set owner = :newOwner where owner = :oldOwner and type = :type" cursor = con.parse(statement) cursor.bind_param(:newOwner,2) cursor.bind_param(:oldOwner,1) cursor.bind_param(:type,"dog") cursor.exec con.commit |

1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 |
Original Data: Id: 1, Name: Duke, Owner: 1, Type: dog Id: 3, Name: Princess, Owner: 1, Type: snake Id: 4, Name: Polly, Owner: 1, Type: bird Id: 5, Name: Rollo, Owner: 1, Type: horse Id: 6, Name: Buster, Owner: 1, Type: dog Id: 7, Name: Fido, Owner: 1, Type: cat Id: 2, Name: Pepe, Owner: 2, Type: bird New Data: Id: 3, Name: Princess, Owner: 1, Type: snake Id: 4, Name: Polly, Owner: 1, Type: bird Id: 5, Name: Rollo, Owner: 1, Type: horse Id: 7, Name: Fido, Owner: 1, Type: cat <strong>Id: 1, Name: Duke, Owner: 2, Type: dog</strong> Id: 2, Name: Pepe, Owner: 2, Type: bird <strong>Id: 6, Name: Buster, Owner: 2, Type: dog</strong> |
In our data, the only unique identifier for lcs_pets is id. Bob may have two dogs, or even two dogs named Duke. Make sure if you intend to change a specific row you use a unique identifier.
It also helps to…
Verify the number of affected rows
Now let’s give Buster back to Bob. This time we will use the unique id column and we will print out the number of rows affected using the return value from cursor.exe.
- Prepare a SQL UPDATE statement.
- Parse the statement to create a cursor.
- Bind the newOwner to 1 and id to 6.
- Execute the statement returning the number of changed rows.
- Commit the transaction.
- Print the number of changed rows.
1 2 3 4 5 6 7 8 |
statement = "update lcs_pets set owner = :newOwner where id = :id" cursor = con.parse(statement) cursor.bind_param(:newOwner,2) cursor.bind_param(:id,6) changed = cursor.exec con.commit printf "Number of rows updated: %d\n\n", changed |

1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 |
Original Data: Id: 3, Name: Princess, Owner: 1, Type: snake Id: 4, Name: Polly, Owner: 1, Type: bird Id: 5, Name: Rollo, Owner: 1, Type: horse Id: 7, Name: Fido, Owner: 1, Type: cat Id: 1, Name: Duke, Owner: 2, Type: dog Id: 2, Name: Pepe, Owner: 2, Type: bird Id: 6, Name: Buster, Owner: 2, Type: dog Number of rows updated: 1 New Data: Id: 3, Name: Princess, Owner: 1, Type: snake Id: 4, Name: Polly, Owner: 1, Type: bird Id: 5, Name: Rollo, Owner: 1, Type: horse Id: 7, Name: Fido, Owner: 1, Type: cat Id: 1, Name: Duke, Owner: 2, Type: dog Id: 2, Name: Pepe, Owner: 2, Type: bird <strong>Id: 6, Name: Buster, Owner: 2, Type: dog</strong> |
Extra Fun 2
Give all birds to Kim that she doesn’t already have and print the number of affected rows.
Your results should be:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 |
Original Data: Id: 3, Name: Princess, Owner: 1, Type: snake Id: 4, Name: Polly, Owner: 1, Type: bird Id: 5, Name: Rollo, Owner: 1, Type: horse Id: 7, Name: Fido, Owner: 1, Type: cat Id: 1, Name: Duke, Owner: 2, Type: dog Id: 2, Name: Pepe, Owner: 2, Type: bird Id: 6, Name: Buster, Owner: 2, Type: dog Number of rows updated: 1 New Data: Id: 3, Name: Princess, Owner: 1, Type: snake Id: 5, Name: Rollo, Owner: 1, Type: horse Id: 7, Name: Fido, Owner: 1, Type: cat Id: 1, Name: Duke, Owner: 2, Type: dog Id: 2, Name: Pepe, Owner: 2, Type: bird <strong>Id: 4, Name: Polly, Owner: 2, Type: bird</strong> Id: 6, Name: Buster, Owner: 2, Type: dog |
Some other things you could try
- Change multiple column values
- Perform an update that changes all rows, if the row count is greater than 2, rollback the change
Series sections
Initial Setup
Create records
Retrieve records
Update records
Delete records