Prepare for the PgBouncer and IPv4 deprecations on 26th January 2024

Home

Tables and Data

Tables are where you store your data.

Tables are similar to excel spreadsheets. They contain columns and rows. For example, this table has 3 "columns" (id, name, description) and 4 "rows" of data:

idnamedescription
1The Phantom MenaceTwo Jedi escape a hostile blockade to find allies and come across a young boy who may bring balance to the Force.
2Attack of the ClonesTen years after the invasion of Naboo, the Galactic Republic is facing a Separatist movement.
3Revenge of the SithAs Obi-Wan pursues a new threat, Anakin acts as a double agent between the Jedi Council and Palpatine and is lured into a sinister plan to rule the galaxy.
4Star WarsLuke Skywalker joins forces with a Jedi Knight, a cocky pilot, a Wookiee and two droids to save the galaxy from the Empire's world-destroying battle station.

There are a few important differences from a spreadsheet, but it's a good starting point if you're new to Relational databases.

Creating tables

When creating a table, it's best practice to add columns at the same time.

Tables and columns

You must define the "data type" of each column when it is created. You can add and remove columns at any time after creating a table.

Supabase provides several options for creating tables. You can use the Dashboard or create them directly using SQL. We provide a SQL editor within the Dashboard, or you can connect to your database and run the SQL queries yourself.

  1. Go to the Table Editor page in the Dashboard.
  2. Click New Table and create a table with the name todos.
  3. Click Save.
  4. Click New Column and create a column with the name task and type text.
  5. Click Save.

Columns

You must define the "data type" when you create a column.

Data types

Every column is a predefined type. PostgreSQL provides many default types, and you can even design your own (or use extensions) if the default types don't fit your needs. You can use any data type that Postgres supports via the SQL editor. We only support a subset of these in the Table Editor in an effort to keep the experience simple for people with less experience with databases.

Show/Hide default data types
NameAliasesDescription
bigintint8signed eight-byte integer
bigserialserial8autoincrementing eight-byte integer
bitfixed-length bit string
bit varyingvarbitvariable-length bit string
booleanboollogical Boolean (true/false)
boxrectangular box on a plane
byteabinary data (“byte array”)
charactercharfixed-length character string
character varyingvarcharvariable-length character string
cidrIPv4 or IPv6 network address
circlecircle on a plane
datecalendar date (year, month, day)
double precisionfloat8double precision floating-point number (8 bytes)
inetIPv4 or IPv6 host address
integerint, int4signed four-byte integer
interval [ fields ]time span
jsontextual JSON data
jsonbbinary JSON data, decomposed
lineinfinite line on a plane
lsegline segment on a plane
macaddrMAC (Media Access Control) address
macaddr8MAC (Media Access Control) address (EUI-64 format)
moneycurrency amount
numericdecimalexact numeric of selectable precision
pathgeometric path on a plane
pg_lsnPostgreSQL Log Sequence Number
pg_snapshotuser-level transaction ID snapshot
pointgeometric point on a plane
polygonclosed geometric path on a plane
realfloat4single precision floating-point number (4 bytes)
smallintint2signed two-byte integer
smallserialserial2autoincrementing two-byte integer
serialserial4autoincrementing four-byte integer
textvariable-length character string
time [ without time zone ]time of day (no time zone)
time with time zonetimetztime of day, including time zone
timestamp [ without time zone ]date and time (no time zone)
timestamp with time zonetimestamptzdate and time, including time zone
tsquerytext search query
tsvectortext search document
txid_snapshotuser-level transaction ID snapshot (deprecated; see pg_snapshot)
uuiduniversally unique identifier
xmlXML data

You can "cast" columns from one type to another, however there can be some incompatibilities between types. For example, if you cast a timestamp to a date, you will lose all the time information that was previously saved.

Primary keys

A table can have a "primary key" - a unique identifier for every row of data. A few tips for Primary Keys:

  • It's recommended to create a Primary Key for every table in your database.
  • You can use any column as a primary key, as long as it is unique for every row.
  • It's common to use a uuid type or a numbered identity column as your primary key.

_10
create table movies (
_10
id bigint generated always as identity primary key
_10
);

In the example above, we have:

  1. created a column called id
  2. assigned the data type bigint
  3. instructed the database that this should be generated always as identity, which means that Postgres will automatically assign a unique number to this column.
  4. Because it's unique, we can also use it as our primary key.

We could also use generated by default as identity, which would allow us to insert our own unique values.


_10
create table movies (
_10
id bigint generated by default as identity primary key
_10
);

Loading data

There are several ways to load data in Supabase. You can load data directly into the database or using the APIs. Use the "Bulk Loading" instructions if you are loading large data sets.

Basic data loading


_11
insert into movies
_11
(name, description)
_11
values
_11
(
_11
'The Empire Strikes Back',
_11
'After the Rebels are brutally overpowered by the Empire on the ice planet Hoth, Luke Skywalker begins Jedi training with Yoda.'
_11
),
_11
(
_11
'Return of the Jedi',
_11
'After a daring mission to rescue Han Solo from Jabba the Hutt, the Rebels dispatch to Endor to destroy the second Death Star.'
_11
);

Bulk data loading

When inserting large data sets it's best to use PostgreSQL's COPY command. This loads data directly from a file into a table. There are several file formats available for copying data: text, csv, binary, JSON, etc.

For example, if you wanted to load a CSV file into your movies table:

./movies.csv

_10
"The Empire Strikes Back", "After the Rebels are brutally overpowered by the Empire on the ice planet Hoth, Luke Skywalker begins Jedi training with Yoda."
_10
"Return of the Jedi", "After a daring mission to rescue Han Solo from Jabba the Hutt, the Rebels dispatch to Endor to destroy the second Death Star."

You would connect to your database directly and load the file with the COPY command:


_10
psql -h DATABASE_URL -p 5432 -d postgres -U postgres \
_10
-c "\COPY movies FROM './movies.csv';"

Additionally use the DELIMITER, HEADER and FORMAT options as defined in the PostgreSQL COPY docs.


_10
psql -h DATABASE_URL -p 5432 -d postgres -U postgres \
_10
-c "\COPY movies FROM './movies.csv' WITH DELIMITER ',' CSV HEADER"

If you receive an error FATAL: password authentication failed for user "postgres", reset your database password in the Database Settings and try again.

Joining tables with foreign keys

Tables can be "joined" together using Foreign Keys.

Foreign Keys

This is where the "Relational" naming comes from, as data typically forms some sort of relationship.

In our "movies" example above, we might want to add a "category" for each movie (for example, "Action", or "Documentary"). Let's create a new table called categories and "link" our movies table.


_10
create table categories (
_10
id bigint generated always as identity primary key,
_10
name text -- category name
_10
);
_10
_10
alter table movies
_10
add column category_id bigint references categories;

You can also create "many-to-many" relationships by creating a "join" table. For example if you had the following situations:

  • You have a list of movies.
  • A movie can have several actors.
  • An actor can perform in several movies.

Schemas

Tables belong to schemas. Schemas are a way of organizing your tables, often for security reasons.

Schemas and tables

If you don't explicitly pass a schema when creating a table, Postgres will assume that you want to create the table in the public schema.

We can create schemas for organizing tables. For example, we might want a private schema which is hidden from our API:


_10
create schema private;

Now we can create tables inside the private schema:


_10
create table private.salaries (
_10
id bigint generated by default as identity primary key,
_10
salary bigint not null,
_10
actor_id bigint not null references public.actors
_10
);

Views

A View is a convenient shortcut to a query. Creating a view does not involve new tables or data. When run, an underlying query is executed, returning its results to the user.

Say we have the following tables from a database of a university:

students

idnametype
1Princess Leiaundergraduate
2Yodagraduate
3Anakin Skywalkergraduate

courses

idtitlecode
1Introduction to PostgresPG101
2Authentication TheoriesAUTH205
3Fundamentals of SupabaseSUP412

grades

idstudent_idcourse_idresult
111B+
213A+
322A
431A-
532A
633B-

Creating a view consisting of all the three tables will look like this:


_12
create view transcripts as
_12
select
_12
students.name,
_12
students.type,
_12
courses.title,
_12
courses.code,
_12
grades.result
_12
from grades
_12
left join students on grades.student_id = students.id
_12
left join courses on grades.course_id = courses.id;
_12
_12
alter view transcripts owner to authenticated;

Once done, we can now access the underlying query with:


_10
select * from transcripts;

When to use views

Views provide the several benefits:

  • Simplicity
  • Consistency
  • Logical Organization
  • Security

Simplicity

As a query becomes more complex, it can be a hassle to call it over and over - especially when we run it regularly. In the example above, instead of repeatedly running:


_10
select
_10
students.name,
_10
students.type,
_10
courses.title,
_10
courses.code,
_10
grades.result
_10
from
_10
grades
_10
left join students on grades.student_id = students.id
_10
left join courses on grades.course_id = courses.id;

We can run this instead:


_10
select * from transcripts;

Additionally, a view behaves like a typical table. We can safely use it in table JOINs or even create new views using existing views.

Consistency

Views ensure that the likelihood of mistakes decreases when repeatedly executing a query. In our example above, we may decide that we want to exclude the course Introduction to Postgres. The query would become:


_11
select
_11
students.name,
_11
students.type,
_11
courses.title,
_11
courses.code,
_11
grades.result
_11
from
_11
grades
_11
left join students on grades.student_id = students.id
_11
left join courses on grades.course_id = courses.id
_11
where courses.code != 'PG101';

Without a view, we would need to go into every dependent query to add the new rule. This would increase in the likelihood of errors and inconsistencies, as well as introducing a lot of effort for a developer. With views, we can alter just the underlying query in the view transcripts. The change will be applied to all applications using this view.

Logical organization

With views, we can give our query a name. This is extremely useful for teams working with the same database. Instead of guessing what a query is supposed to do, a well-named view can easily explain it. For example, by looking at the name of the view transcripts, we can infer that the underlying query might involve the students, courses, and grades tables.

Security

Views can restrict the amount and type of data presented to a user. Instead of allowing a user direct access to a set of tables, we provide them a view instead. We can prevent them from reading sensitive columns by excluding them from the underlying query.

Materialized views

A materialized view is a form of view but it also stores the results to disk. In subsequent reads of a materialized view, the time taken to return its results would be much faster than a conventional view. This is because the data is readily available for a materialized view while the conventional view executes the underlying query each time it is called.

Using our example above, a materialized view can be created like this:


_11
create materialized view transcripts as
_11
select
_11
students.name,
_11
students.type,
_11
courses.title,
_11
courses.code,
_11
grades.result
_11
from
_11
grades
_11
left join students on grades.student_id = students.id
_11
left join courses on grades.course_id = courses.id;

Reading from the materialized view is the same as a conventional view:


_10
select * from transcripts;

Refreshing materialized views

Unfortunately, there is a trade-off - data in materialized views are not always up to date. We need to refresh it regularly to prevent the data from becoming too stale. To do so:


_10
refresh materialized view transcripts;

It's up to you how regularly refresh your materialized views, and it's probably different for each view depending on its use-case.

Materialized views vs conventional views

Materialized views are useful when execution times for queries or views are too slow. These could likely occur in views or queries involving multiple tables and billions of rows. When using such a view, however, there should be tolerance towards data being outdated. Some use-cases for materialized views are internal dashboards and analytics.

Creating a materialized view is not a solution to inefficient queries. You should always seek to optimize a slow running query even if you are implementing a materialized view.

Resources