Here we provide an overview of how to perform simple operations in SQL. This tutorial is only intended to give you an introduction and is in no way a complete tutorial on SQL. This tutorial is adapted from the PostgreSQL tutorial.
DuckDB's SQL dialect closely follows the conventions of the PostgreSQL dialect. The few exceptions to this are listed on the PostgreSQL compatibility page.
In the examples that follow, we assume that you have installed the DuckDB Command Line Interface (CLI) shell. See the installation page for information on how to install the CLI.
Concepts
DuckDB is a relational database management system (RDBMS). That means it is a system for managing data stored in relations. A relation is essentially a mathematical term for a table.
Each table is a named collection of rows. Each row of a given table has the same set of named columns, and each column is of a specific data type. Tables themselves are stored inside schemas, and a collection of schemas constitutes the entire database that you can access.
Creating a New Table
You can create a new table by specifying the table name, along with all column names and their types:
CREATE TABLE weather (
city VARCHAR,
temp_lo INTEGER, -- minimum temperature on a day
temp_hi INTEGER, -- maximum temperature on a day
prcp FLOAT,
date DATE
);
You can enter this into the shell with the line breaks. The command is not terminated until the semicolon.
White space (i.e., spaces, tabs, and newlines) can be used freely in SQL commands. That means you can type the command aligned differently than above, or even all on one line. Two dash characters (--
) introduce comments. Whatever follows them is ignored up to the end of the line. SQL is case-insensitive about keywords and identifiers. When returning identifiers, their original cases are preserved.
In the SQL command, we first specify the type of command that we want to perform: CREATE TABLE
. After that follows the parameters for the command. First, the table name, weather
, is given. Then the column names and column types follow.
city VARCHAR
specifies that the table has a column called city
that is of type VARCHAR
. VARCHAR
specifies a data type that can store text of arbitrary length. The temperature fields are stored in an INTEGER
type, a type that stores integer numbers (i.e., whole numbers without a decimal point). FLOAT
columns store single precision floating-point numbers (i.e., numbers with a decimal point). DATE
stores a date (i.e., year, month, day combination). DATE
only stores the specific day, not a time associated with that day.
DuckDB supports the standard SQL types INTEGER
, SMALLINT
, FLOAT
, DOUBLE
, DECIMAL
, CHAR(n)
, VARCHAR(n)
, DATE
, TIME
and TIMESTAMP
.
The second example will store cities and their associated geographical location:
CREATE TABLE cities (
name VARCHAR,
lat DECIMAL,
lon DECIMAL
);
Finally, it should be mentioned that if you don't need a table any longer or want to recreate it differently you can remove it using the following command:
DROP TABLE ⟨tablename⟩;
Populating a Table with Rows
The insert statement is used to populate a table with rows:
INSERT INTO weather
VALUES ('San Francisco', 46, 50, 0.25, '1994-11-27');
Constants that are not numeric values (e.g., text and dates) must be surrounded by single quotes (''
), as in the example. Input dates for the date type must be formatted as 'YYYY-MM-DD'
.
We can insert into the cities
table in the same manner.
INSERT INTO cities
VALUES ('San Francisco', -194.0, 53.0);
The syntax used so far requires you to remember the order of the columns. An alternative syntax allows you to list the columns explicitly:
INSERT INTO weather (city, temp_lo, temp_hi, prcp, date)
VALUES ('San Francisco', 43, 57, 0.0, '1994-11-29');
You can list the columns in a different order if you wish or even omit some columns, e.g., if the prcp
is unknown:
INSERT INTO weather (date, city, temp_hi, temp_lo)
VALUES ('1994-11-29', 'Hayward', 54, 37);
Tip Many developers consider explicitly listing the columns better style than relying on the order implicitly.
Please enter all the commands shown above so you have some data to work with in the following sections.
Alternatively, you can use the COPY
statement. This is faster for large amounts of data because the COPY
command is optimized for bulk loading while allowing less flexibility than INSERT
. An example with weather.csv
would be:
COPY weather
FROM 'weather.csv';
Where the file name for the source file must be available on the machine running the process. There are many other ways of loading data into DuckDB, see the corresponding documentation section for more information.
Querying a Table
To retrieve data from a table, the table is queried. A SQL SELECT
statement is used to do this. The statement is divided into a select list (the part that lists the columns to be returned), a table list (the part that lists the tables from which to retrieve the data), and an optional qualification (the part that specifies any restrictions). For example, to retrieve all the rows of table weather, type:
SELECT *
FROM weather;
Here *
is a shorthand for “all columns”. So the same result would be had with:
SELECT city, temp_lo, temp_hi, prcp, date
FROM weather;
The output should be:
city | temp_lo | temp_hi | prcp | date |
---|---|---|---|---|
San Francisco | 46 | 50 | 0.25 | 1994-11-27 |
San Francisco | 43 | 57 | 0.0 | 1994-11-29 |
Hayward | 37 | 54 | NULL | 1994-11-29 |
You can write expressions, not just simple column references, in the select list. For example, you can do:
SELECT city, (temp_hi + temp_lo) / 2 AS temp_avg, date
FROM weather;
This should give:
city | temp_avg | date |
---|---|---|
San Francisco | 48.0 | 1994-11-27 |
San Francisco | 50.0 | 1994-11-29 |
Hayward | 45.5 | 1994-11-29 |
Notice how the AS
clause is used to relabel the output column. (The AS
clause is optional.)
A query can be “qualified” by adding a WHERE
clause that specifies which rows are wanted. The WHERE
clause contains a Boolean (truth value) expression, and only rows for which the Boolean expression is true are returned. The usual Boolean operators (AND
, OR
, and NOT
) are allowed in the qualification. For example, the following retrieves the weather of San Francisco on rainy days:
SELECT *
FROM weather
WHERE city = 'San Francisco'
AND prcp > 0.0;
Result:
city | temp_lo | temp_hi | prcp | date |
---|---|---|---|---|
San Francisco | 46 | 50 | 0.25 | 1994-11-27 |
You can request that the results of a query be returned in sorted order:
SELECT *
FROM weather
ORDER BY city;
city | temp_lo | temp_hi | prcp | date |
---|---|---|---|---|
Hayward | 37 | 54 | NULL | 1994-11-29 |
San Francisco | 43 | 57 | 0.0 | 1994-11-29 |
San Francisco | 46 | 50 | 0.25 | 1994-11-27 |
In this example, the sort order isn't fully specified, and so you might get the San Francisco rows in either order. But you'd always get the results shown above if you do:
SELECT *
FROM weather
ORDER BY city, temp_lo;
You can request that duplicate rows be removed from the result of a query:
SELECT DISTINCT city
FROM weather;
city |
---|
San Francisco |
Hayward |
Here again, the result row ordering might vary. You can ensure consistent results by using DISTINCT
and ORDER BY
together:
SELECT DISTINCT city
FROM weather
ORDER BY city;
Joins between Tables
Thus far, our queries have only accessed one table at a time. Queries can access multiple tables at once, or access the same table in such a way that multiple rows of the table are being processed at the same time. A query that accesses multiple rows of the same or different tables at one time is called a join query. As an example, say you wish to list all the weather records together with the location of the associated city. To do that, we need to compare the city column of each row of the weather
table with the name column of all rows in the cities
table, and select the pairs of rows where these values match.
This would be accomplished by the following query:
SELECT *
FROM weather, cities
WHERE city = name;
city | temp_lo | temp_hi | prcp | date | name | lat | lon |
---|---|---|---|---|---|---|---|
San Francisco | 46 | 50 | 0.25 | 1994-11-27 | San Francisco | -194.000 | 53.000 |
San Francisco | 43 | 57 | 0.0 | 1994-11-29 | San Francisco | -194.000 | 53.000 |
Observe two things about the result set:
- There is no result row for the city of Hayward. This is because there is no matching entry in the
cities
table for Hayward, so the join ignores the unmatched rows in theweather
table. We will see shortly how this can be fixed. - There are two columns containing the city name. This is correct because the lists of columns from the
weather
andcities
tables are concatenated. In practice this is undesirable, though, so you will probably want to list the output columns explicitly rather than using*
:
SELECT city, temp_lo, temp_hi, prcp, date, lon, lat
FROM weather, cities
WHERE city = name;
city | temp_lo | temp_hi | prcp | date | lon | lat |
---|---|---|---|---|---|---|
San Francisco | 46 | 50 | 0.25 | 1994-11-27 | 53.000 | -194.000 |
San Francisco | 43 | 57 | 0.0 | 1994-11-29 | 53.000 | -194.000 |
Since the columns all had different names, the parser automatically found which table they belong to. If there were duplicate column names in the two tables you'd need to qualify the column names to show which one you meant, as in:
SELECT weather.city, weather.temp_lo, weather.temp_hi,
weather.prcp, weather.date, cities.lon, cities.lat
FROM weather, cities
WHERE cities.name = weather.city;
It is widely considered good style to qualify all column names in a join query, so that the query won't fail if a duplicate column name is later added to one of the tables.
Join queries of the kind seen thus far can also be written in this alternative form:
SELECT *
FROM weather
INNER JOIN cities ON weather.city = cities.name;
This syntax is not as commonly used as the one above, but we show it here to help you understand the following topics.
Now we will figure out how we can get the Hayward records back in. What we want the query to do is to scan the weather
table and for each row to find the matching cities row(s). If no matching row is found we want some “empty values” to be substituted for the cities
table's columns. This kind of query is called an outer join. (The joins we have seen so far are inner joins.) The command looks like this:
SELECT *
FROM weather
LEFT OUTER JOIN cities ON weather.city = cities.name;
city | temp_lo | temp_hi | prcp | date | name | lat | lon |
---|---|---|---|---|---|---|---|
San Francisco | 46 | 50 | 0.25 | 1994-11-27 | San Francisco | -194.000 | 53.000 |
San Francisco | 43 | 57 | 0.0 | 1994-11-29 | San Francisco | -194.000 | 53.000 |
Hayward | 37 | 54 | NULL | 1994-11-29 | NULL | NULL | NULL |
This query is called a left outer join because the table mentioned on the left of the join operator will have each of its rows in the output at least once, whereas the table on the right will only have those rows output that match some row of the left table. When outputting a left-table row for which there is no right-table match, empty (null) values are substituted for the right-table columns.
Aggregate Functions
Like most other relational database products, DuckDB supports aggregate functions. An aggregate function computes a single result from multiple input rows. For example, there are aggregates to compute the count
, sum
, avg
(average), max
(maximum) and min
(minimum) over a set of rows.
As an example, we can find the highest low-temperature reading anywhere with:
SELECT max(temp_lo)
FROM weather;
max(temp_lo) |
---|
46 |
If we wanted to know what city (or cities) that reading occurred in, we might try:
SELECT city
FROM weather
WHERE temp_lo = max(temp_lo); -- WRONG
but this will not work since the aggregate max cannot be used in the WHERE
clause. (This restriction exists because the WHERE
clause determines which rows will be included in the aggregate calculation; so obviously it has to be evaluated before aggregate functions are computed.) However, as is often the case the query can be restated to accomplish the desired result, here by using a subquery:
SELECT city
FROM weather
WHERE temp_lo = (SELECT max(temp_lo) FROM weather);
city |
---|
San Francisco |
This is OK because the subquery is an independent computation that computes its own aggregate separately from what is happening in the outer query.
Aggregates are also very useful in combination with GROUP BY
clauses. For example, we can get the maximum low temperature observed in each city with:
SELECT city, max(temp_lo)
FROM weather
GROUP BY city;
city | max(temp_lo) |
---|---|
San Francisco | 46 |
Hayward | 37 |
Which gives us one output row per city. Each aggregate result is computed over the table rows matching that city. We can filter these grouped rows using HAVING
:
SELECT city, max(temp_lo)
FROM weather
GROUP BY city
HAVING max(temp_lo) < 40;
city | max(temp_lo) |
---|---|
Hayward | 37 |
which gives us the same results for only the cities that have all temp_lo
values below 40. Finally, if we only care about cities whose names begin with S
, we can use the LIKE
operator:
SELECT city, max(temp_lo)
FROM weather
WHERE city LIKE 'S%' -- (1)
GROUP BY city
HAVING max(temp_lo) < 40;
More information about the LIKE
operator can be found in the pattern matching page.
It is important to understand the interaction between aggregates and SQL's WHERE
and HAVING
clauses. The fundamental difference between WHERE
and HAVING
is this: WHERE
selects input rows before groups and aggregates are computed (thus, it controls which rows go into the aggregate computation), whereas HAVING
selects group rows after groups and aggregates are computed. Thus, the WHERE
clause must not contain aggregate functions; it makes no sense to try to use an aggregate to determine which rows will be inputs to the aggregates. On the other hand, the HAVING
clause always contains aggregate functions.
In the previous example, we can apply the city name restriction in WHERE
, since it needs no aggregate. This is more efficient than adding the restriction to HAVING
, because we avoid doing the grouping and aggregate calculations for all rows that fail the WHERE
check.
Updates
You can update existing rows using the UPDATE
command. Suppose you discover the temperature readings are all off by 2 degrees after November 28. You can correct the data as follows:
UPDATE weather
SET temp_hi = temp_hi - 2, temp_lo = temp_lo - 2
WHERE date > '1994-11-28';
Look at the new state of the data:
SELECT *
FROM weather;
city | temp_lo | temp_hi | prcp | date |
---|---|---|---|---|
San Francisco | 46 | 50 | 0.25 | 1994-11-27 |
San Francisco | 41 | 55 | 0.0 | 1994-11-29 |
Hayward | 35 | 52 | NULL | 1994-11-29 |
Deletions
Rows can be removed from a table using the DELETE
command. Suppose you are no longer interested in the weather of Hayward. Then you can do the following to delete those rows from the table:
DELETE FROM weather
WHERE city = 'Hayward';
All weather records belonging to Hayward are removed.
SELECT *
FROM weather;
city | temp_lo | temp_hi | prcp | date |
---|---|---|---|---|
San Francisco | 46 | 50 | 0.25 | 1994-11-27 |
San Francisco | 41 | 55 | 0.0 | 1994-11-29 |
One should be cautious when issuing statements of the following form:
DELETE FROM ⟨table_name⟩;
Warning Without a qualification,
DELETE
will remove all rows from the given table, leaving it empty. The system will not request confirmation before doing this.