Tutorial

How To Update Data in SQL

Published on October 21, 2020

Manager, Developer Education

How To Update Data in SQL

Introduction

When working with a database, there may be times when you need to change data that’s already been inserted into it. For example, you may need to correct a misspelled entry or perhaps you have new information to add to an incomplete record. Structured Query Language — more commonly known as SQL — provides the UPDATE keyword which allows users to change existing data in a table.

This guide outlines how you can use SQL’s UPDATE syntax to change data in one or more tables. It also explains how SQL handles UPDATE operations that conflict with foreign key constraints.

Prerequisites

To follow this guide, you’ll need a computer running some type of relational database management system (RDBMS) that uses SQL. The instructions and examples in this guide were validated using the following environment:

Note: Please note that many RDBMSs use their own unique implementations of SQL. Although the commands outlined in this tutorial will work on most RDBMSs, the exact syntax or output may differ if you test them on a system other than MySQL.

  • You’ll also need a database with some tables loaded with sample data which you can use to practice updating SQL data. We encourage you to go through the following Connecting to MySQL and Setting up a Sample Database section for details on how to connect to a MySQL server and create the testing database used in examples throughout this guide.

Connecting To MySQL and Setting Up a Sample Database

If your SQL database system runs on a remote server, SSH into your server from your local machine:

  1. ssh sammy@your_server_ip

Then open up the MySQL server prompt, replacing sammy with the name of your MySQL user account:

  1. mysql -u sammy -p

Create a database named updateDB:

  1. CREATE DATABASE updateDB;

If the database was created successfully, you’ll receive output like this:

Output
Query OK, 1 row affected (0.01 sec)

To select the updateDB database, run the following USE statement:

  1. USE updateDB;
Output
Database changed

After selecting the updateDB database, create a couple tables within it. For the examples used in this guide, imagine that you run a talent agency and have decided to begin tracking your clients and their performances in an SQL database. You plan to start off with two tables, the first of which will store information about your clients. You decide this table needs four columns:

  • clientID: each client’s identification number, expressed with the int data type. This column will also serve as the table’s primary key, with each value functioning as a unique identifier for its respective row
  • name: each client’s name, expressed using the varchar data type with a maximum of 20 characters
  • routine: a brief description of each client’s primary performance genre, again expressed using the varchar data type but with a maximum of 30 characters
  • performanceFee: a column to record each client’s standard performance fee, it uses the decimal data type with any values in this column limited to a maximum of five digits in length with two of those digits to the right of the decimal point. Thus, the range of values allowed in this column goes from -999.99 to 999.99

Create a table named clients that has these four columns:

  1. CREATE TABLE clients
  2. (clientID int PRIMARY KEY,
  3. name varchar(20),
  4. routine varchar(30),
  5. standardFee decimal (5,2)
  6. );

The second table will store information about your clients’ performances at a local venue. You decide this table needs five columns:

  • showID: similar to the clientID column, this column will hold a unique identification number for each show, expressed with the int data type. Likewise this column will serve as primary key for the shows table
  • showDate: the date of each performance. This column’s values are expressed using the date data type which uses the 'YYYY-MM-DD' format
  • clientID: the ID number of the client performing at the show, expressed as an integer
  • attendance: the number of attendees at each performance, expressed as an integer
  • ticketPrice: the price of an individual ticket at each show. This column uses the decimal data type with any values in this column limited to a maximum of four digits in length with two of those digits to the right of the decimal point, so the range of values allowed in this column is -99.99 to 99.99

To ensure that the clientID column only holds values that represent valid client ID numbers, you decide to apply a foreign key constraint to the clientID column that references the clients table’s clientID column. A foreign key constraint is a way to express a relationship between two tables by requiring that values in the column on which it applies must already exist in the column that it references. In the following example, the FOREIGN KEY constraint requires that any value added to the clientID column in the shows table must already exist in the client table’s clientID column.

Create a table named clients that has these five columns:

  1. CREATE TABLE shows
  2. (showID int PRIMARY KEY,
  3. showDate date,
  4. clientID int,
  5. attendance int,
  6. ticketPrice decimal (4,2),
  7. CONSTRAINT client_fk
  8. FOREIGN KEY (clientID)
  9. REFERENCES clients(clientID)
  10. );

Note that this example provides a name for the foreign key constraint: client_fk. MySQL will automatically generate a name for any constraint you add, but defining one here will be useful when we need to reference this constraint later on.

Next, run the following INSERT INTO statement to load the clients table with five rows of sample data:

  1. INSERT INTO clients
  2. VALUES
  3. (1, 'Gladys', 'song and dance', 180),
  4. (2, 'Catherine', 'standup', 99.99),
  5. (3, 'Georgeanna', 'standup', 45),
  6. (4, 'Wanda', 'song and dance', 200),
  7. (5, 'Ann', 'trained squirrel', 79.99);

Then run another INSERT INTO statement to load the shows table with ten rows of sample data:

  1. INSERT INTO shows
  2. VALUES
  3. (1, '2019-12-25', 4, 124, 15),
  4. (2, '2020-01-11', 5, 84, 29.50),
  5. (3, '2020-01-17', 3, 170, 12.99),
  6. (4, '2020-01-31', 5, 234, 14.99),
  7. (5, '2020-02-08', 1, 86, 25),
  8. (6, '2020-02-14', 3, 102, 39.5),
  9. (7, '2020-02-15', 2, 101, 26.50),
  10. (8, '2020-02-27', 2, 186, 19.99),
  11. (9, '2020-03-06', 4, 202, 30),
  12. (10, '2020-03-07', 5, 250, 8.99);

With that, you’re ready to follow the rest of the guide and begin learning about how to update data with SQL.

Updating Data in a Single Table

The general syntax of an UPDATE statement looks like this:

  1. UPDATE table_name
  2. SET column_name = value_expression
  3. WHERE conditions_apply;

Following the UPDATE keyword is the name of the table storing the data you want to update. After that is a SET clause which specifies which column’s data should be updated and how. Think of the SET clause as setting values in the specified column as equal to whatever value expression you provide.

In SQL, a value expression — sometimes known as a scalar expression — is any expression that will return a single value for every row to be updated. This could be a string literal, or a mathematical operation performed on existing numeric values in the column. You must include at least one value assignment in every UPDATE statement, but you can include more than one to update data in multiple columns.

After the SET clause is a WHERE clause. Including a WHERE clause in an UPDATE statement like in this example syntax allows you to filter out any rows that you don’t want to update. A WHERE clause is entirely optional in UPDATE statements, but if you don’t include one the operation will update every row in the table.

To illustrate how SQL handles UPDATE operations, start by taking a look at all the data in the clients table. The following query includes an asterisk (*) which is SQL shorthand representing every column in the table, so this query will return all the data from every column in the clients table:

  1. SELECT * FROM clients;
Output
+----------+------------+------------------+-------------+ | clientID | name | routine | standardFee | +----------+------------+------------------+-------------+ | 1 | Gladys | song and dance | 180.00 | | 2 | Catherine | standup | 99.99 | | 3 | Georgeanna | standup | 45.00 | | 4 | Wanda | song and dance | 200.00 | | 5 | Ann | trained squirrel | 79.99 | +----------+------------+------------------+-------------+ 5 rows in set (0.00 sec)

Say, for example, that you notice Katherine’s name is misspelled — it should begin with a “K” but in the table it begins with a “C” — so you decide to change that value by running the following UPDATE statement. This operation updates values in the name column by changing the name value of any row with the name Catherine to Katherine:

  1. UPDATE clients
  2. SET name = 'Katherine'
  3. WHERE name = 'Catherine';
Output
Query OK, 1 row affected (0.01 sec) Rows matched: 1 Changed: 1 Warnings: 0

This output indicates that only one row was updated. You can confirm this by running the previous SELECT query again:

  1. SELECT * FROM clients;
Output
+----------+------------+------------------+-------------+ | clientID | name | routine | standardFee | +----------+------------+------------------+-------------+ | 1 | Gladys | song and dance | 180.00 | | 2 | Katherine | standup | 99.99 | | 3 | Georgeanna | standup | 45.00 | | 4 | Wanda | song and dance | 200.00 | | 5 | Ann | trained squirrel | 79.99 | +----------+------------+------------------+-------------+ 5 rows in set (0.00 sec)

This output shows that the value formerly reading Catherine has indeed been changed to Katherine.

This example updated only one value in the name column. However, you can update multiple values with a less exclusive WHERE clause.

To illustrate, imagine that you negotiate standard performance fees for all your clients who perform stand-up comedy or song and dance routines. The following statement will update values in the standardFee column by setting them equal to 140.

Note that this example’s WHERE clause includes a LIKE operator so it only updates the performanceFee value for each client whose routine value matches the specified wildcard pattern, 's%'. In other words, it will update the performance fee of any performer whose routine starts with the letter “s”:

  1. UPDATE clients
  2. SET standardFee = 140
  3. WHERE routine LIKE 's%';
Output
Query OK, 4 rows affected (0.00 sec) Rows matched: 4 Changed: 4 Warnings: 0

If you query the contents of the clients table once again, the result set will confirm that four of your clients now have the same performance fee:

  1. SELECT * FROM clients;
Output
+----------+------------+------------------+-------------+ | clientID | name | routine | standardFee | +----------+------------+------------------+-------------+ | 1 | Gladys | song and dance | 140.00 | | 2 | Katherine | standup | 140.00 | | 3 | Georgeanna | standup | 140.00 | | 4 | Wanda | song and dance | 140.00 | | 5 | Ann | trained squirrel | 79.99 | +----------+------------+------------------+-------------+ 5 rows in set (0.00 sec)

If any columns in your table hold numeric values, you can update them using an arithmetic operation in the SET clause. To illustrate, say that you also negotiate a forty percent increase for each of your clients’ performance fees. To reflect this in the clients table, you could run an UPDATE operation like this:

  1. UPDATE clients
  2. SET standardFee = standardFee * 1.4;
Output
Query OK, 5 rows affected, 1 warning (0.00 sec) Rows matched: 5 Changed: 5 Warnings: 1

Note: Notice that this output indicates the update resulted in a warning. Oftentimes, MySQL will issue a warning when it’s forced to make a change to your data because of a column or table’s definition.

MySQL provides the SHOW WARNINGS shortcut that can help explain any warnings you receive:

  1. SHOW WARNINGS;
Output
+-------+------+--------------------------------------------------+ | Level | Code | Message | +-------+------+--------------------------------------------------+ | Note | 1265 | Data truncated for column 'standardFee' at row 5 | +-------+------+--------------------------------------------------+ 1 row in set (0.00 sec)

This output informs us that the database system issued the warning because it had to truncate one of the new standardFee values so it would conform to the decimal format — five digits with two to the right of the decimal point — defined previously.

Query the clients table once more to confirm that each of the clients’ performance fees have increased by forty percent.

  1. SELECT * FROM clients;
Output
+----------+------------+------------------+-------------+ | clientID | name | routine | standardFee | +----------+------------+------------------+-------------+ | 1 | Gladys | song and dance | 196.00 | | 2 | Katherine | standup | 196.00 | | 3 | Georgeanna | standup | 196.00 | | 4 | Wanda | song and dance | 196.00 | | 5 | Ann | trained squirrel | 111.99 | +----------+------------+------------------+-------------+ 5 rows in set (0.00 sec)

As mentioned previously, you can also update data in multiple columns with a single UPDATE statement. To do this, you must specify every column you want to update, following each with the respective value expression, and then separate each column and value expression pair with a comma.

For example, say that you learn that the venue where your clients perform had misreported the number of attendees for all of Georgeanna and Wanda’s shows. By coincidence, you also happened to enter the wrong ticket price for each of their performances.

Before updating the data in the shows table, run the following query to retrieve all the data currently held within it:

  1. SELECT * FROM shows;
Output
+--------+------------+----------+------------+-------------+ | showID | showDate | clientID | attendance | ticketPrice | +--------+------------+----------+------------+-------------+ | 1 | 2019-12-25 | 4 | 124 | 15.00 | | 2 | 2020-01-11 | 5 | 84 | 29.50 | | 3 | 2020-01-17 | 3 | 170 | 12.99 | | 4 | 2020-01-31 | 5 | 234 | 14.99 | | 5 | 2020-02-08 | 1 | 86 | 25.00 | | 6 | 2020-02-14 | 3 | 102 | 39.50 | | 7 | 2020-02-15 | 2 | 101 | 26.50 | | 8 | 2020-02-27 | 2 | 186 | 19.99 | | 9 | 2020-03-06 | 4 | 202 | 30.00 | | 10 | 2020-03-07 | 5 | 250 | 8.99 | +--------+------------+----------+------------+-------------+ 10 rows in set (0.01 sec)

To reflect the actual numbers and prices, you update the table to add twenty attendees to each of their performances and increase each of their ticketPrice values by fifty percent. You could do so with an operation like the following:

  1. UPDATE shows
  2. SET attendance = attendance + 20,
  3. ticketPrice = ticketPrice * 1.5
  4. WHERE clientID IN
  5. (SELECT clientID
  6. FROM clients
  7. WHERE name = 'Georgeanna' OR name = 'Wanda');
Output
Query OK, 4 rows affected, 1 warning (0.00 sec) Rows matched: 4 Changed: 4 Warnings: 1

Notice that this example uses a subquery in the WHERE clause to return Georgeanna and Wanda’s clientID values from the clients table. Oftentimes, abstract values like identification numbers can be hard to remember, but this method of using a subquery to find a value can be helpful when you only know certain attributes about the records in question.

After updating the shows table, query it once again to confirm that the changes went through as expected:

  1. SELECT * FROM shows;
Output
+--------+------------+----------+------------+-------------+ | showID | showDate | clientID | attendance | ticketPrice | +--------+------------+----------+------------+-------------+ | 1 | 2019-12-25 | 4 | 144 | 22.50 | | 2 | 2020-01-11 | 5 | 84 | 29.50 | | 3 | 2020-01-17 | 3 | 190 | 19.49 | | 4 | 2020-01-31 | 5 | 234 | 14.99 | | 5 | 2020-02-08 | 1 | 86 | 25.00 | | 6 | 2020-02-14 | 3 | 122 | 59.25 | | 7 | 2020-02-15 | 2 | 101 | 26.50 | | 8 | 2020-02-27 | 2 | 186 | 19.99 | | 9 | 2020-03-06 | 4 | 222 | 45.00 | | 10 | 2020-03-07 | 5 | 250 | 8.99 | +--------+------------+----------+------------+-------------+ 10 rows in set (0.00 sec)

Once again, this output indicates that the UPDATE statement completed successfully.

Using JOIN Clauses to Update Data in Multiple Tables

Up to this point, this guide has only shown how to update data in one table at a time. However, some SQL implementations allow you to update multiple columns in multiple tables by temporarily combining the tables with a JOIN clause.

Here’s the general syntax you can use to update multiple tables with a JOIN clause:

  1. UPDATE table_1 JOIN table_2
  2. ON table_1.related_column = table_2.related_column
  3. SET table_1.column_name = value_expression,
  4. table_2.column_name = value_expression
  5. WHERE conditions_apply;

This example syntax begins with the UPDATE keyword followed by the names of two tables, separated by a JOIN clause. Following that is the ON clause, which describes how the query should join the two tables together.

In most implementations, you can join tables by finding matches between any set of columns that have what the SQL standard refers to as “JOIN eligible” data types. This means that, in general, you can join any column holding numeric data with any other column that holds numeric data, regardless of their respective data types. Likewise, you can join any columns that hold character values with any other column holding character data.

Note that because JOIN clauses compare the contents of more than one table, this example syntax specifies which table to select each column from by preceding the name of the column with the name of the table and a period. This is known as a fully qualified column reference. You can specify which table a column should be selected from like this for any operation, although it’s typically only used to improve clarity when working with multiple tables.

To illustrate with the sample tables created previously, run the following UPDATE statement. This will join the clients and shows tables on their respective clientID columns, and then update the routine and ticketPrice values for Gladys’s record in the clients table and each of her performances listed in the shows table:

  1. UPDATE clients JOIN shows
  2. USING (clientID)
  3. SET clients.routine = 'mime',
  4. shows.ticketPrice = 30
  5. WHERE name = 'Gladys';
Output
Query OK, 2 rows affected (0.01 sec) Rows matched: 2 Changed: 2 Warnings: 0

Notice that this example joins the tables with the USING keyword instead of the ON keyword used in the previous example syntax. This is possible because both tables have a clientID column that share a similar data type.

For a more in-depth tutorial on JOIN operations, see our guide on How To Use Joins in SQL.

Changing Foreign Key UPDATE Behavior

By default, any UPDATE statement that would cause a conflict with a FOREIGN KEY constraint will fail.

Recall from the Connecting to MySQL and Setting up a Sample Database section of the Prerequisites that the clientID column of the shows table is a foreign key that references the clientID column of the clients table. This means that any value entered into the shows table’s clientID column must already exist in that of the clients table.

If you attempt to update the clientID value of a record in the clients table that also appears in the clientID column of the shows table, it will cause an error:

  1. UPDATE clients
  2. SET clientID = 9
  3. WHERE name = 'Ann';
Output
ERROR 1217 (23000): Cannot delete or update a parent row: a foreign key constraint fails

You can avoid this error by replacing the existing foreign key constraint with one that treats UPDATE operations differently.

Note: Not every relational database management system or engine allows you to add or remove a constraint from an existing table as outlined in the following paragraphs. If you’re using an RDBMS other than MySQL, you should consult its official documentation to understand what limitations it has for managing constraints.

To replace the current constraint, you must first remove it with an ALTER TABLE statement. Recall that in the CREATE TABLE statement for shows, we defined client_fk as the name for the table’s FOREIGN KEY constraint:

  1. ALTER TABLE shows
  2. DROP FOREIGN KEY client_fk;
Output
Query OK, 0 rows affected (0.01 sec) Records: 0 Duplicates: 0 Warnings: 0

Following that, create a new foreign key constraint that’s configured to treat UPDATE operations in a way that makes sense for the given use case. Aside from the default setting which prohibits UPDATE statements that violate the foreign key, there are two other options available on most RDBMSs:

  • ON UPDATE SET NULL: This option will allow you to update records from the parent table, and will reset any values in the child table that reference them as NULL.
  • ON UPDATE CASCADE: When you update a row in the parent table, this option will cause SQL to automatically update any records that reference it in the child table so that they align with the new value in the parent table.

For the purposes of this example, ON UPDATE SET NULL doesn’t make sense. After all, if you change one of your clients’ identification numbers but don’t remove them from the clients table, they should still be associated with their performances in the shows table. Their new identification number should be reflected in their performances’ records, so the ON UPDATE CASCADE option makes more sense for our purposes.

To add a FOREIGN KEY constraint that follows the ON UPDATE CASCADE behavior, run the following ALTER TABLE statement. This creates a new constraint named new_client_fk which replicates the previous constraint definition, but includes the ON UPDATE CASCADE option:

  1. ALTER TABLE shows
  2. ADD CONSTRAINT new_client_fk
  3. FOREIGN KEY (clientID)
  4. REFERENCES clients (clientID)
  5. ON UPDATE CASCADE;
Output
Query OK, 10 rows affected (0.02 sec) Records: 10 Duplicates: 0 Warnings: 0

This output tells you that the operation impacted all ten rows in the shows table.

Note: Instead of altering a table’s definition to change how a foreign key handles UPDATE operations, you can define this behavior from the start in the CREATE TABLE statement like this:

  1. CREATE TABLE shows
  2. (showID int PRIMARY KEY,
  3. showDate date,
  4. clientID int,
  5. attendance int,
  6. ticketPrice decimal (4,2),
  7. CONSTRAINT client_fk
  8. FOREIGN KEY (clientID)
  9. REFERENCES clients(clientID)
  10. ON UPDATE CASCADE
  11. );

Following that, you’ll be able to update the clientID value of any record in the clients table, and those changes will cascade down to any rows in the shows table that reference it:

  1. UPDATE clients
  2. SET clientID = 9
  3. WHERE name = 'Ann';
Output
Query OK, 1 row affected (0.01 sec) Rows matched: 1 Changed: 1 Warnings: 0

Although this output says it only affected one row, it will have also updated the clientID value of any performance records in the shows table associated with Ann. To confirm this, run the following query to retrieve all the data from the shows table:

  1. SELECT * FROM shows;
Output
+--------+------------+----------+------------+-------------+ | showID | showDate | clientID | attendance | ticketPrice | +--------+------------+----------+------------+-------------+ | 1 | 2019-12-25 | 4 | 144 | 22.50 | | 2 | 2020-01-11 | 9 | 84 | 29.50 | | 3 | 2020-01-17 | 3 | 190 | 19.49 | | 4 | 2020-01-31 | 9 | 234 | 14.99 | | 5 | 2020-02-08 | 1 | 86 | 30.00 | | 6 | 2020-02-14 | 3 | 122 | 59.25 | | 7 | 2020-02-15 | 2 | 101 | 26.50 | | 8 | 2020-02-27 | 2 | 186 | 19.99 | | 9 | 2020-03-06 | 4 | 222 | 45.00 | | 10 | 2020-03-07 | 9 | 250 | 8.99 | +--------+------------+----------+------------+-------------+ 10 rows in set (0.00 sec)

As expected, the update made to the clientID column in the clients table cascaded down to the associated rows in the shows table.

Conclusion

By reading this guide, you learned how to change existing records in or more tables using SQL’s UPDATE statement. You also learned how SQL handles UPDATE operations that conflict with foreign key constraints, and how to change that default behavior.

The commands outlined here should work on any database management system that uses SQL. Keep in mind that every SQL database uses its own unique implementation of the language, so you should consult your DBMS’s official documentation for a more complete description of how it handles UPDATE operations and what options are available for them.

If you’d like to learn more about working with SQL, we encourage you to check out the other tutorials in this series on How To Use SQL.

Thanks for learning with the DigitalOcean Community. Check out our offerings for compute, storage, networking, and managed databases.

Learn more about our products


Tutorial Series: How To Use SQL

Series Description

Structured Query Language — commonly known as SQL — is a language used to define, control, manipulate, and query data held in a relational database. SQL has been widely adopted since it was first developed in the 1970s, and today it’s the predominant language used to manage relational database management systems.

Ideal for managing structured data (data that can fit neatly into an existing data model), SQL is an essential tool for developers and system administrators in a wide variety of contexts. Also, because of its maturity and prevalence, candidates with SQL experience are highly sought after for jobs across a number of industries.

This series is intended to help you get started with using SQL. It includes a mix of conceptual articles and tutorials which provide introductions to various SQL concepts and practices. You can also use the entries in this series for reference while you continue to hone your skills with SQL.

Note: Please be aware that the tutorials in this series use MySQL in examples, but many RDBMSs use their own unique implementations of SQL. Although the commands outlined in this tutorial will work on most RDBMSs, the exact syntax or output may differ if you test them on a system other than MySQL.

About the authors
Default avatar

Manager, Developer Education

Technical Writer @ DigitalOcean

Still looking for an answer?

Ask a questionSearch for more help

Was this helpful?
 
Leave a comment


This textbox defaults to using Markdown to format your answer.

You can type !ref in this text area to quickly search our full set of tutorials, documentation & marketplace offerings and insert the link!

Try DigitalOcean for free

Click below to sign up and get $200 of credit to try our products over 60 days!

Sign up

Join the Tech Talk
Success! Thank you! Please check your email for further details.

Please complete your information!

Become a contributor for community

Get paid to write technical tutorials and select a tech-focused charity to receive a matching donation.

DigitalOcean Documentation

Full documentation for every DigitalOcean product.

Resources for startups and SMBs

The Wave has everything you need to know about building a business, from raising funding to marketing your product.

Get our newsletter

Stay up to date by signing up for DigitalOcean’s Infrastructure as a Newsletter.

New accounts only. By submitting your email you agree to our Privacy Policy

The developer cloud

Scale up as you grow — whether you're running one virtual machine or ten thousand.

Get started for free

Sign up and get $200 in credit for your first 60 days with DigitalOcean.*

*This promotional offer applies to new accounts only.