New connection management docs (#29166)
* recreated connecting-to-postgres * adding GUI quickstart section with DBeaver * moved psql and pgadmin docs to GUI quickstart * added Prisma installation docs. Moved postgres.js and Drizzle into own section * added connection management docs * moved supavisor troubleshooting guide into troubleshooting section. Probably should not merge without adding more guides * updated IPv4 Add ons docs * removed typo * Update apps/docs/content/guides/platform/ipv4-address.mdx Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * Update apps/docs/content/guides/platform/ipv4-address.mdx Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * Update apps/docs/content/guides/database/supavisor.mdx Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * Update apps/docs/content/guides/database/prisma.mdx Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * Update apps/docs/content/guides/database/connection-management.mdx Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * Update apps/docs/content/guides/database/connection-management.mdx Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * Update apps/docs/components/Navigation/NavigationMenu/NavigationMenu.constants.ts Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * removed repetition in connection-management | added photos * Update apps/docs/content/guides/database/connecting-to-postgres.mdx Co-authored-by: Stas <sts@abc3.dev> * Update apps/docs/content/guides/platform/ipv4-address.mdx Co-authored-by: Stas <sts@abc3.dev> * Update apps/docs/content/guides/database/connection-management.mdx Co-authored-by: Stas <sts@abc3.dev> * Update apps/docs/content/guides/database/connecting-to-postgres.mdx Co-authored-by: Stas <sts@abc3.dev> * Update apps/docs/content/guides/platform/ipv4-address.mdx Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> * Update apps/docs/content/guides/database/connecting-to-postgres.mdx Co-authored-by: Stas <sts@abc3.dev> * updated proxy suggestions * added redirects * added images to connection-management guide * added unique ids to titles in prisma-troubleshooting section * added images to connection guide * added new images to prisma guide * reformatted admonition --------- Co-authored-by: Brian Brennglass <brian@Brians-MacBook-Pro.local> Co-authored-by: Charis <26616127+charislam@users.noreply.github.com> Co-authored-by: Stas <sts@abc3.dev>
@@ -749,6 +749,10 @@ export const database: NavMenuConstant = {
|
||||
name: 'Partitioning your tables',
|
||||
url: '/guides/database/partitions',
|
||||
},
|
||||
{
|
||||
name: 'Managing connections',
|
||||
url: '/guides/database/connection-management',
|
||||
},
|
||||
],
|
||||
},
|
||||
{
|
||||
@@ -829,6 +833,52 @@ export const database: NavMenuConstant = {
|
||||
name: 'Debugging performance issues',
|
||||
url: '/guides/database/debugging-performance',
|
||||
},
|
||||
{
|
||||
name: 'Supavisor',
|
||||
url: '/guides/database/supavisor',
|
||||
},
|
||||
],
|
||||
},
|
||||
{
|
||||
name: 'ORM Quickstarts',
|
||||
url: undefined,
|
||||
items: [
|
||||
{
|
||||
name: 'Prisma',
|
||||
url: '/guides/database/prisma',
|
||||
items: [
|
||||
{
|
||||
name: 'Prisma troubleshooting',
|
||||
url: '/guides/database/prisma/prisma-troubleshooting',
|
||||
},
|
||||
],
|
||||
},
|
||||
{
|
||||
name: 'Drizzle',
|
||||
url: '/guides/database/drizzle',
|
||||
},
|
||||
{
|
||||
name: 'Postgres.js',
|
||||
url: '/guides/database/postgres-js',
|
||||
},
|
||||
],
|
||||
},
|
||||
{
|
||||
name: 'GUI quickstarts',
|
||||
url: undefined,
|
||||
items: [
|
||||
{
|
||||
name: 'pgAdmin',
|
||||
url: '/guides/database/pgadmin',
|
||||
},
|
||||
{
|
||||
name: 'PSQL',
|
||||
url: '/guides/database/psql',
|
||||
},
|
||||
{
|
||||
name: 'DBeaver',
|
||||
url: '/guides/database/dbeaver',
|
||||
},
|
||||
],
|
||||
},
|
||||
{
|
||||
|
||||
@@ -7,30 +7,85 @@ subtitle: 'Explore the options for connecting to your Postgres database.'
|
||||
|
||||
Supabase provides several options for programmatically connecting to your Postgres database:
|
||||
|
||||
1. Programmatic access using the Data APIs
|
||||
1. Connection pooling for scalable connections
|
||||
1. The Data APIs
|
||||
1. Using one of the many [Client Libraries](/docs/reference)
|
||||
1. Direct connections using the built-in Postgres connection system
|
||||
1. Using one of the many [Client Libraries](https://supabase.com/docs#client-libraries)
|
||||
|
||||
<Admonition type="caution">
|
||||
|
||||
Direct database connections will start resolving to an IPv6 address. Starting from January 26, 2024, projects will be gradually migrated to this behavior. If you connect to your database using the REST or GraphQL endpoints, this doesn't affect you. If you use the database connection string, see the GitHub discussion on [how to prepare for IPv6](https://github.com/orgs/supabase/discussions/17817).
|
||||
|
||||
</Admonition>
|
||||
1. Connection pooling for scalable connections
|
||||
|
||||
## Data APIs
|
||||
|
||||
Supabase provides auto-updating Data APIs. These are the easiest way to get started if you are managing data (fetching, inserting, updating). We provide several types of API to suit your preferences:
|
||||
Supabase's Data APIs are the easiest way to get started if you are managing data (fetching, inserting, updating). We provide several types of API to suit your preferences:
|
||||
|
||||
- [REST](/docs/guides/api): interact with your database through a REST interface.
|
||||
- [GraphQL](/docs/guides/graphql/api): interact with your database through a GraphQL interface.
|
||||
- [Realtime](/docs/guides/realtime#realtime-api): listen to database changes over websockets.
|
||||
|
||||
## Connection pooler
|
||||
## Client libraries
|
||||
|
||||
A "connection pool" is a system (external to Postgres) which manages Postgres connections.
|
||||
Supabase offers [client libraries](/docs/reference) for popular programming languages. These libraries provide a convenient wrapper around the Data APIs, making it easier to interact with your database using your preferred language.
|
||||
|
||||
When a client makes a request, the pooler "allocates" an available connection to the client. When the client transaction or session is completed the connection is returned to the pool and is free to be used by another client.
|
||||
## Connecting to external libraries and tools
|
||||
|
||||
Beyond the [Supabase client-libraries](/docs/guides/api/rest/client-libs), Supabase provides three connection strings for direct database access, compatible with all postgres libraries, such as [Prisma](/docs/guides/database/prisma) and [Drizzle](/docs/guides/database/drizzle), as well as tools like [PSQL](/docs/guides/database/psql) and [pgAdmin](/docs/guides/database/pgadmin).
|
||||
|
||||
You can find these connection strings in your [Database Settings](https://supabase.com/dashboard/project/_/settings/database).
|
||||
|
||||
### Direct connections:
|
||||
|
||||
It connects directly to your Postgres instance. It is ideal for persistent servers, such as virtual machines (VMs) and long-lasting containers. Examples include AWS EC2 machines, Fly.io VMs, and DigitalOcean Droplets.
|
||||
|
||||
<Admonition type="caution">
|
||||
|
||||
Direct connections use IPv6 by default. If your environment doesn't support IPv6 or you're unsure but still want to use a direct connection, check out the [networking guide](/docs/guides/platform/ipv4-address#supabase-and-ipv6-compatibility) for more info.
|
||||
|
||||
</Admonition>
|
||||
|
||||
```md
|
||||
// Example String
|
||||
postgresql://postgres:[YOUR-PASSWORD]@db.apbkobhfnmcqqzqeeqss.supabase.co:5432/postgres
|
||||
```
|
||||
|
||||
You can find the direct connection string in the [Database settings](https://supabase.com/dashboard/project/_/settings/database) inside the dashboard:
|
||||
|
||||
1. Go to the `Settings` section.
|
||||
2. Click `Database`.
|
||||
3. Under `Connection string`, make sure `Use connection pooling` is unchecked. Copy the URI.
|
||||
|
||||
### Supavisor session mode (port 5432):
|
||||
|
||||
In Session mode, Supavisor acts as an IPv4 proxy. It allows developers in IPv4-only environments to access a direct-connection experience without needing the IPv4 add-on.
|
||||
|
||||
```md
|
||||
// Example String
|
||||
postgres://postgres.apbkobhfnmcqqzqeeqss:[YOUR-PASSWORD]@aws-0-ca-central-1.pooler.supabase.com:5432/postgres
|
||||
```
|
||||
|
||||
### Transaction mode (port 6543):
|
||||
|
||||
<Admonition type="caution">
|
||||
|
||||
Transaction mode does not support [prepared statements](https://postgresql.org/docs/current/sql-prepare.html). To avoid errors, [turn off prepared statements](https://github.com/orgs/supabase/discussions/28239) for your specific connection library.
|
||||
|
||||
</Admonition>
|
||||
|
||||
Supavisor in transaction mode forms hot connections with the database and only allows clients to access them when a query is pending. It has amazing scaling capacity, and is best used with temporary servers, such as serverless/Edge Functions or auto-scaling servers.
|
||||
|
||||
```md
|
||||
// Example String
|
||||
postgres://postgres.apbkobhfnmcqqzqeeqss:[YOUR-PASSWORD]@aws-0-ca-central-1.pooler.supabase.com:6543/postgres
|
||||
```
|
||||
|
||||
## Connection pooling in-depth
|
||||
|
||||
### Application side poolers
|
||||
|
||||
Application-side poolers are built into connection libraries and API servers, such as Prisma, SQLAlchemy, and PostgREST. They maintain several active connections with Postgres or a server-side pooler, reducing the overhead of establishing connections between queries. When deploying to static architecture, such as long-standing containers or VMs, application-side poolers are satisfactory on their own.
|
||||
|
||||
### Serverside poolers
|
||||
|
||||
Postgres connections are like WebSocket, once established, they are preserved until the client (application server) disconnects. A server might only make a single 10 ms query, but needlessly reserve its database connection for seconds or longer.
|
||||
|
||||
Serverside-poolers, such as Supabase's [Supavisor](https://github.com/supabase/supavisor) in transaction mode, sit between clients and the database and can be thought of as load balancers for Postgres connections.
|
||||
|
||||
<Image
|
||||
alt="New migration files trigger migrations on the preview instance."
|
||||
@@ -43,47 +98,7 @@ When a client makes a request, the pooler "allocates" an available connection to
|
||||
zoomable
|
||||
/>
|
||||
|
||||
Every Supabase project comes with a connection pooler for managing connections to your database. The pooler provides 2 important services:
|
||||
|
||||
1. It manages connections for applications that connect and disconnect from the database frequently. For example, serverless functions and ORMs such as Prisma, Drizzle, and Kysely often make and drop connections to the database. If they connected directly each time, they would quickly exhaust your database server's memory. To connect to your database efficiently with such tools, you need a pooler.
|
||||
2. It provides an IPv4 endpoint to connect to your database, which you can use if your network provider doesn't support IPv6. This is unlike the direct database connection, which resolves to an IPv6 address, unless you've enabled the [IPv4 add-on](https://supabase.com/docs/guides/platform/ipv4-address).
|
||||
|
||||
<Admonition type="tip">
|
||||
|
||||
The connection pooler is available in 2 modes: `Transaction` and `Session`.
|
||||
|
||||
</Admonition>
|
||||
|
||||
Transaction mode is recommended if you are connecting from serverless environments. A connection is assigned to the client for the duration of a transaction. Two consecutive transactions from the same client can be executed over two different connections. Some session-based Postgres features such as prepared statements are _not available_ with this option.
|
||||
|
||||
Session mode is similar to connecting to your database directly. There is full support for prepared statements in this mode. When a new client connects, a connection is assigned to the client until it disconnects. You might run into pooler connection limits since the connection is held till the client disconnects.
|
||||
|
||||
You can find the connection pool config in the [Database settings](/dashboard/project/_/settings/database) inside the dashboard:
|
||||
|
||||
1. Go to the `Settings` section.
|
||||
2. Click `Database`.
|
||||
3. Under `Connection string`, make sure `Use connection pooling` is checked. Copy the URI.
|
||||
|
||||
### Pre-requisites
|
||||
|
||||
The connection pooler on Supabase projects currently uses the `pgbouncer` Postgres role to make an initial connection to the `postgres` database. If these permissions are revoked, you will not be able to use the pooler until the requisite permissions have been granted.
|
||||
|
||||
## Direct connections
|
||||
|
||||
You can also use a direct connection to connect directly to your Postgres database. By default, you can connect to it via IPv6, which isn't supported by all networks. If you need an IPv4 address, use the [connection pooler](#connection-pooler) instead or enable the [IPv4 add-on](https://supabase.com/docs/guides/platform/ipv4-address).
|
||||
|
||||
You can find the direct connection string in the [Database settings](https://supabase.com/dashboard/project/_/settings/database) inside the dashboard:
|
||||
|
||||
1. Go to the `Settings` section.
|
||||
2. Click `Database`.
|
||||
3. Under `Connection string`, make sure `Use connection pooling` is unchecked. Copy the URI.
|
||||
|
||||
## Choosing a connection method
|
||||
|
||||
- Are you performing operations supported by the Data APIs? We recommend using the APIs.
|
||||
- Are you connecting to your database and then _disconnecting_ immediately (for example, are you running your code in a serverless environment)? Use the connection pooler in transaction mode.
|
||||
- Are you on a network that doesn't support IPv6? Use the connection pooler. (If you need a long-lived connection, for example for prepared statements, use session mode.)
|
||||
- Are you connecting to your database and _maintaining_ a connection, and does your network support IPv6? Use a direct connection.
|
||||
They maintain hot connections with the database and intelligently share them with clients only when needed, maximizing the amount of queries a single connection can service. They're best used to manage queries from auto-scaling systems, such as edge and serverless functions.
|
||||
|
||||
## Connecting with SSL
|
||||
|
||||
@@ -93,317 +108,34 @@ You can obtain your connection info and Server root certificate from your applic
|
||||
|
||||

|
||||
|
||||
## Integrations
|
||||
## Choosing a connection method
|
||||
|
||||
### Connecting with Drizzle
|
||||
- **Data APIs:** Best for operations supported by the Data APIs.
|
||||
- **Supavisor Pooler:**
|
||||
- **Transaction mode (port 6543):** Best for serverless/edge functions and rapidly auto-scaling servers
|
||||
- **Session mode (port 5432):** For long-lived servers, such as virtual machines (VM) and enduring containers (if IPv6 is unsupported)
|
||||
- **Direct Connections:** For long-lived servers, such as VMs and enduring containers (if IPv6 is supported or the IPv4 Add-On is enabled).
|
||||
|
||||
[Drizzle ORM](https://github.com/drizzle-team/drizzle-orm) is a TypeScript ORM for SQL databases designed with maximum type safety in mind. You can use their ORM to connect to your database.
|
||||
## Quickstart connection guides
|
||||
|
||||
<StepHikeCompact>
|
||||
<Admonition type="tip">
|
||||
|
||||
<StepHikeCompact.Step step={1}>
|
||||
If you'd like us to add a new quickstart guide, share your [feedback](https://supabase.com/dashboard/support/new), and we'll try to add it going forwards.
|
||||
|
||||
<StepHikeCompact.Details title="Install">
|
||||
</Admonition>
|
||||
|
||||
Install Drizzle and related dependencies.
|
||||
### External libraries
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
- [Prisma](/docs/guides/database/prisma)
|
||||
- [Drizzle](/docs/guides/database/drizzle)
|
||||
- [Postgres.js](/docs/guides/database/drizzle)
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
### External tools
|
||||
|
||||
```shell
|
||||
npm i drizzle-orm postgres
|
||||
npm i -D drizzle-kit
|
||||
```
|
||||
- [pgAdmin](/docs/guides/database/pgadmin)
|
||||
- [PSQL](/docs/guides/database/psql)
|
||||
- [DBeaver](/docs/guides/database/dbeaver)
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
## Resources
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
|
||||
<StepHikeCompact.Details title="Create your models">
|
||||
|
||||
Create a `schema.ts` file and define your models.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts schema.ts
|
||||
import { pgTable, serial, text, varchar } from "drizzle-orm/pg-core";
|
||||
|
||||
export const users = pgTable('users', {
|
||||
id: serial('id').primaryKey(),
|
||||
fullName: text('full_name'),
|
||||
phone: varchar('phone', { length: 256 }),
|
||||
});
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
|
||||
<StepHikeCompact.Details title="Connect">
|
||||
|
||||
Connect to your database using the Connection Pooler.
|
||||
|
||||
In your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database), make sure `Use connection pooler` is checked, then copy the URI and save it as the `DATABASE_URL` environment variable. Remember to replace the password placeholder with your actual database password.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts db.ts
|
||||
import 'dotenv/config'
|
||||
|
||||
import { drizzle } from 'drizzle-orm/postgres-js'
|
||||
import postgres from 'postgres'
|
||||
|
||||
const connectionString = process.env.DATABASE_URL
|
||||
|
||||
// Disable prefetch as it is not supported for "Transaction" pool mode
|
||||
export const client = postgres(connectionString, { prepare: false })
|
||||
export const db = drizzle(client);
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
|
||||
### Connecting with pgAdmin
|
||||
|
||||
[`pgAdmin`](https://www.pgadmin.org/) is a GUI tool for managing Postgres databases. You can use it to connect to your database via SSL:
|
||||
|
||||
<StepHikeCompact>
|
||||
|
||||
<StepHikeCompact.Step step={1}>
|
||||
|
||||
<StepHikeCompact.Details title="Register">
|
||||
|
||||
Register a new Postgres server.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
<Image
|
||||
alt="Register a new postgres server."
|
||||
src={{
|
||||
dark: '/docs/img/guides/database/connecting-to-postgres/pgadmin/register-server-pgAdmin.png?v=2',
|
||||
light:
|
||||
'/docs/img/guides/database/connecting-to-postgres/pgadmin/register-server-pgAdmin--light.png',
|
||||
}}
|
||||
/>
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
|
||||
<StepHikeCompact.Details title="Name">
|
||||
|
||||
Name your server.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||

|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
|
||||
<StepHikeCompact.Details title="Connect">
|
||||
|
||||
Add the connection info. Go to your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database). Make sure `Use connection pooling` is enabled. Switch the connection mode to `Session` and copy your connection parameters. Fill in your Database password that you made when creating your project (It can be reset in Database Settings above if you don't have it).
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||

|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={4}>
|
||||
|
||||
<StepHikeCompact.Details title="SSL">
|
||||
|
||||
Navigate to the Parameters tab and select connection parameter as Root Certificate. Next navigate to the Root certificate input, it will open up a file-picker modal. Select the certificate you downloaded from [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database) and save the server details. PgAdmin should now be able to connect to your Postgres via SSL.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||

|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
|
||||
### Connecting with psql
|
||||
|
||||
[`psql`](https://www.postgresql.org/docs/current/app-psql.html) is a command-line tool that comes with Postgres.
|
||||
|
||||
Download your [SSL certificate](#connecting-with-ssl) to `/path/to/prod-supabase.cer`.
|
||||
|
||||
Find your connection settings. Go to your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database) and make sure `Use connection pooling` is checked. Change the connection mode to `Session`, and copy the parameters into the connection string:
|
||||
|
||||
```shell
|
||||
psql "sslmode=verify-full sslrootcert=/path/to/prod-supabase.cer host=[CLOUD_PROVIDER]-0-[REGION].pooler.supabase.com dbname=postgres user=postgres.[PROJECT_REF]"
|
||||
```
|
||||
|
||||
### Connecting with Prisma
|
||||
|
||||
Refer to our [Prisma integration guide](https://supabase.com/partners/integrations/prisma) for more details.
|
||||
|
||||
### Connecting with Postgres.js
|
||||
|
||||
[Postgres.js](https://github.com/porsager/postgres) is a full-featured PostgreSQL client for Node.js and Deno.
|
||||
|
||||
<StepHikeCompact>
|
||||
|
||||
<StepHikeCompact.Step step={1}>
|
||||
|
||||
<StepHikeCompact.Details title="Install">
|
||||
|
||||
Install Postgres.js and related dependencies.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```shell
|
||||
npm i postgres
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
|
||||
<StepHikeCompact.Details title="Connect">
|
||||
|
||||
Create a `db.js` file with the connection details.
|
||||
|
||||
To get your connection details, go to your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database). Make sure `Use connection pooling` is enabled. Choose `Transaction Mode` if you're on a platform with transient connections, such as a serverless function, and `Session Mode` if you have a long-lived connection. Copy the URI and save it as the environment variable `DATABASE_URL`.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts
|
||||
// db.js
|
||||
import postgres from 'postgres'
|
||||
|
||||
const connectionString = process.env.DATABASE_URL
|
||||
const sql = postgres(connectionString)
|
||||
|
||||
export default sql
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
|
||||
<StepHikeCompact.Details title="Execute commands">
|
||||
|
||||
Use the connection to execute commands.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts
|
||||
import sql from './db.js'
|
||||
|
||||
async function getUsersOver(age) {
|
||||
const users = await sql`
|
||||
select name, age
|
||||
from users
|
||||
where age > ${ age }
|
||||
`
|
||||
// users = Result [{ name: "Walter", age: 80 }, { name: 'Murray', age: 68 }, ...]
|
||||
return users
|
||||
}
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
|
||||
## Troubleshooting Supavisor
|
||||
|
||||
Connection pooler logs are found [here](https://supabase.com/dashboard/project/_/logs/pooler-logs). The following are common errors and their solutions:
|
||||
|
||||
- Max client connections reached
|
||||
This error happens when the number of connections to Supavisor is more than [the allowed limit of your compute add-on](https://supabase.com/docs/guides/platform/compute-add-ons). Upgrade the database to a higher compute add-on to increase the number of Supavisor connections.
|
||||
|
||||
- Connection failed \{:error, :eaddrnotavail} to 'db.xxx.supabase.co':5432
|
||||
Supavisor cannot connect to the customer database. This is usually caused if the target database is unable to respond.
|
||||
|
||||
- Connection failed \{:error, :nxdomain} to 'db.xxx.supabase.co':5432
|
||||
Supavisor cannot connect to the customer database. This is usually caused if the target database is unable to respond.
|
||||
|
||||
- Connection closed when state was authentication
|
||||
This error happens when either the database doesn’t exist or if the user doesn't have the right credentials.
|
||||
|
||||
- Subscribe error: \{:error, :worker_not_found}
|
||||
This log event is emitted when the client tries to connect to the database, but Supavisor does not have the necessary information to route the connection. Try reconnecting to the database as it can take some time for the project information to propagate to Supavisor.
|
||||
|
||||
- Subscribe error: \{:error, \{:badrpc, \{:error, \{:erpc, :timeout}}}}
|
||||
This is a timeout error when the communication between different Supavisor nodes takes longer than expected. Try reconnecting to the database.
|
||||
|
||||
- Terminating with reason :client_termination when state was :busy
|
||||
This error happens when the client terminates the connection before the connection with the database is completed.
|
||||
|
||||
## Finding your database hostname
|
||||
|
||||
Your database’s hostname is crucial for establishing a direct connection. It resolves to the underlying IP address of your database. To find your hostname, navigate to your [Database Settings](/dashboard/project/_/settings/database).
|
||||
|
||||
Note that the pooler (connection pooler) has a different IP than your database. To reveal the database host and direct connection string, hide the pooler connection string.
|
||||
|
||||
Example hostname: `db.<PROJECT_REF>.supabase.co`
|
||||
|
||||
## Managing your IP address
|
||||
|
||||
To determine your current IP address, you can use an IP address [lookup website](https://whatismyipaddress.com/hostname-ip) or the terminal command:
|
||||
|
||||
```shell
|
||||
nslookup db.<PROJECT_REF>.supabase.co
|
||||
```
|
||||
|
||||
This command queries the domain name servers to find the IP address of the given hostname.
|
||||
|
||||
Example IPv6 Address: `2a05:d014:1c06:5f0c:d7a9:8616:bee2:30df`
|
||||
|
||||
### IPv6 address
|
||||
|
||||
Upon project creation, a static IPv6 address is assigned. This address might change when:
|
||||
|
||||
- A project is paused or resumed.
|
||||
- The database is upgraded.
|
||||
|
||||
### IPv4 address
|
||||
|
||||
Opting for the static [IPv4 add-on](https://supabase.com/docs/guides/platform/ipv4-address) provides a more stable connection address. The IPv4 address remains constant unless the project is paused or resumed.
|
||||
|
||||
Unlike the IPv6 address, upgrading your database doesn't affect the IPv4 address.
|
||||
- [Connection management](/docs/guides/database/connection-management)
|
||||
|
||||
80
apps/docs/content/guides/database/connection-management.mdx
Normal file
@@ -0,0 +1,80 @@
|
||||
---
|
||||
id: 'connection-management'
|
||||
title: 'Connection management'
|
||||
description: 'Managing connections'
|
||||
subtitle: 'Using your connections resourcefully'
|
||||
---
|
||||
|
||||
## Connections
|
||||
|
||||
Every [Compute Add-On](/docs/guides/platform/compute-add-ons) has a pre-configured direct connection count and Supavisor pool size. This guide discusses ways to observe and manage them resourcefully.
|
||||
|
||||
### Configuring Supavisor's pool size
|
||||
|
||||
You can change how many database connections Supavisor can manage by altering the pool size in the "Connection pooling configuration" section of the [Database Settings](/dashboard/project/_/settings/database):
|
||||
|
||||

|
||||
|
||||
The general rule is that if you are heavily using the PostgREST database API, you should be conscientious about raising your pool size past 40%. Otherwise, you can commit 80% to the pool. This leaves adequate room for the Authentication server and other utilities.
|
||||
|
||||
These numbers are generalizations and depends on other Supabase products that you use and the extent of their usage. The actual values depend on your peak connection usage. For instance, if you were only using 80 connections in a week period and your database max connections is set to 500, then realistically you could allocate the difference of 420 (minus a reasonable buffer) to service more demand.
|
||||
|
||||
## Monitoring connections
|
||||
|
||||
### Capturing historical usage
|
||||
|
||||
Supabase offers a Grafana Dashboard that records and visualizes over 200 project metrics, including connections. For setup instructions, check the [metrics docs](/docs/guides/platform/metrics).
|
||||
|
||||
Its "Client Connections" graph displays connections for both Supavisor and Postgres
|
||||

|
||||
|
||||
### Observing live connections
|
||||
|
||||
`pg_stat_activity` is a special view that keeps track of processes being run by your database, including live connections. It's particularly useful for determining if idle clients are hogging connection slots.
|
||||
|
||||
Query to get all live connections:
|
||||
|
||||
```sql
|
||||
SELECT
|
||||
pg_stat_activity.pid as connection_id,
|
||||
ssl,
|
||||
datname as database,
|
||||
usename as connected_role,
|
||||
application_name,
|
||||
client_addr as IP,
|
||||
query,
|
||||
query_start,
|
||||
state,
|
||||
backend_start
|
||||
FROM pg_stat_ssl
|
||||
JOIN pg_stat_activity
|
||||
ON pg_stat_ssl.pid = pg_stat_activity.pid;
|
||||
```
|
||||
|
||||
Interpreting the query:
|
||||
|
||||
| Column | Description |
|
||||
| ---------------- | ------------------------------------------------- |
|
||||
| connection_id | connection id |
|
||||
| ssl | Indicates if SSL is in use |
|
||||
| database | Name of the connected database (usually postgres) |
|
||||
| usename | Role of the connected user |
|
||||
| application_name | Name of the connecting application |
|
||||
| client_addr | IP address of the connecting server |
|
||||
| query | Last query executed by the connection |
|
||||
| query_start | Time when the last query was executed |
|
||||
| state | Querying state: active or idle |
|
||||
| backend_start | Timestamp of the connection's establishment |
|
||||
|
||||
The usename can be used to identify the source:
|
||||
|
||||
| Role | API/Tool |
|
||||
| ---------------------------- | ------------------------------------------------------------------------- |
|
||||
| supabase_admin | Used by Supabase to configure projects and for monitoring |
|
||||
| authenticator | Data API (PostgREST) |
|
||||
| supabase_auth_admin | Auth |
|
||||
| supabase_storage_admin | Storage |
|
||||
| supabase_realtime_admin | Realtime |
|
||||
| supabase_replication_admin | Synchronizes Read Replicas |
|
||||
| postgres | Supabase Dashboard and External Tools (e.g., Prisma, SQLAlchemy, PSQL...) |
|
||||
| Custom roles defined by user | External Tools (e.g., Prisma, SQLAlchemy, PSQL...) |
|
||||
96
apps/docs/content/guides/database/dbeaver.mdx
Normal file
@@ -0,0 +1,96 @@
|
||||
---
|
||||
id: 'dbeaver'
|
||||
title: 'Connecting with DBeaver'
|
||||
breadcrumb: 'GUI Quickstarts'
|
||||
hideToc: true
|
||||
---
|
||||
|
||||
If you do not have DBeaver, you can download it from its [website](https://dbeaver.io/download/).
|
||||
|
||||
<StepHikeCompact>
|
||||
|
||||
<StepHikeCompact.Step step={1}>
|
||||
<StepHikeCompact.Details title="Create a new database connection">
|
||||
Create a new database connection
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||

|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
<StepHikeCompact.Details title="Select PostgreSQL" />
|
||||
|
||||
<StepHikeCompact.Code>
|
||||

|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
<StepHikeCompact.Details title="Get Your Credentials">
|
||||
Inside the Dashboard's [Database Settings](https://supabase.com/dashboard/project/_/settings/database), note your session mode's:
|
||||
- host
|
||||
- username
|
||||
|
||||
You will also need your database's password. If you forgot it, you can generate a new one in the settings.
|
||||
<Admonition type="note">
|
||||
If you're in an [IPv6 environment](https://github.com/orgs/supabase/discussions/27034) or have the IPv4 Add-On, you can use the direct connection string instead of Supavisor in Session mode.
|
||||
</Admonition>
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||

|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={4}>
|
||||
<StepHikeCompact.Details title="Fill out credentials">
|
||||
In DBeaver's Main menu, add your host, username, and password
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||

|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={5}>
|
||||
<StepHikeCompact.Details title="Download certificate">
|
||||
In the [Database Settings](https://supabase.com/dashboard/project/_/settings/database), download your SSL certificate.
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||

|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={6}>
|
||||
<StepHikeCompact.Details title="Secure your connection">
|
||||
In DBeaver's SSL tab, add your SSL certificate
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||

|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={7}>
|
||||
<StepHikeCompact.Details title="Connect">
|
||||
Test your connection and then click finish. You should now be able to interact with your database with DBeaver
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||

|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
92
apps/docs/content/guides/database/drizzle.mdx
Normal file
@@ -0,0 +1,92 @@
|
||||
---
|
||||
id: 'drizzle'
|
||||
title: 'Drizzle'
|
||||
description: 'Drizzle Quickstart'
|
||||
breadcrumb: 'ORM Quickstarts'
|
||||
hideToc: true
|
||||
---
|
||||
|
||||
### Connecting with Drizzle
|
||||
|
||||
[Drizzle ORM](https://github.com/drizzle-team/drizzle-orm) is a TypeScript ORM for SQL databases designed with maximum type safety in mind. You can use their ORM to connect to your database.
|
||||
|
||||
<Admonition type="note">
|
||||
|
||||
If you plan on solely using Drizzle instead of the Supabase Data API (PostgREST), you can turn off the latter in the [API Settings](https://supabase.com/dashboard/project/_/settings/api).
|
||||
|
||||
</Admonition>
|
||||
<StepHikeCompact>
|
||||
|
||||
<StepHikeCompact.Step step={1}>
|
||||
|
||||
<StepHikeCompact.Details title="Install">
|
||||
|
||||
Install Drizzle and related dependencies.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```shell
|
||||
npm i drizzle-orm postgres
|
||||
npm i -D drizzle-kit
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
|
||||
<StepHikeCompact.Details title="Create your models">
|
||||
|
||||
Create a `schema.ts` file and define your models.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts schema.ts
|
||||
import { pgTable, serial, text, varchar } from "drizzle-orm/pg-core";
|
||||
|
||||
export const users = pgTable('users', {
|
||||
id: serial('id').primaryKey(),
|
||||
fullName: text('full_name'),
|
||||
phone: varchar('phone', { length: 256 }),
|
||||
});
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
|
||||
<StepHikeCompact.Details title="Connect">
|
||||
|
||||
Connect to your database using the Connection Pooler.
|
||||
|
||||
In your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database), make sure `Use connection pooler` is checked, then copy the URI and save it as the `DATABASE_URL` environment variable. Remember to replace the password placeholder with your actual database password.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts db.ts
|
||||
import 'dotenv/config'
|
||||
|
||||
import { drizzle } from 'drizzle-orm/postgres-js'
|
||||
import postgres from 'postgres'
|
||||
|
||||
const connectionString = process.env.DATABASE_URL
|
||||
|
||||
// Disable prefetch as it is not supported for "Transaction" pool mode
|
||||
export const client = postgres(connectionString, { prepare: false })
|
||||
export const db = drizzle(client);
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
85
apps/docs/content/guides/database/pgadmin.mdx
Normal file
@@ -0,0 +1,85 @@
|
||||
---
|
||||
id: 'pgadmin'
|
||||
title: 'Connecting with pgAdmin'
|
||||
breadcrumb: 'GUI Quickstarts'
|
||||
hideToc: true
|
||||
---
|
||||
|
||||
[`pgAdmin`](https://www.pgadmin.org/) is a GUI tool for managing Postgres databases. You can use it to connect to your database via SSL.
|
||||
|
||||
<StepHikeCompact>
|
||||
|
||||
<StepHikeCompact.Step step={1}>
|
||||
|
||||
<StepHikeCompact.Details title="Register">
|
||||
|
||||
Register a new Postgres server.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
<Image
|
||||
alt="Register a new postgres server."
|
||||
src={{
|
||||
dark: '/docs/img/guides/database/connecting-to-postgres/pgadmin/register-server-pgAdmin.png?v=2',
|
||||
light:
|
||||
'/docs/img/guides/database/connecting-to-postgres/pgadmin/register-server-pgAdmin--light.png',
|
||||
}}
|
||||
/>
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
|
||||
<StepHikeCompact.Details title="Name">
|
||||
|
||||
Name your server.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||

|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
|
||||
<StepHikeCompact.Details title="Connect">
|
||||
|
||||
Add the connection info. Go to your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database). Make sure `Use connection pooling` is enabled. Switch the connection mode to `Session` and copy your connection parameters. Fill in your Database password that you made when creating your project (It can be reset in Database Settings above if you don't have it).
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||

|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={4}>
|
||||
|
||||
<StepHikeCompact.Details title="SSL">
|
||||
|
||||
Download your SSL certificate from Dashboard's [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database).
|
||||
|
||||
In pgAdmin, navigate to the Parameters tab and select connection parameter as Root Certificate. Next navigate to the Root certificate input, it will open up a file-picker modal. Select the certificate you downloaded earlier and save the server details. PgAdmin should now be able to connect to your Postgres via SSL.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||

|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
87
apps/docs/content/guides/database/postgres-js.mdx
Normal file
@@ -0,0 +1,87 @@
|
||||
---
|
||||
id: 'postgres-js'
|
||||
title: 'Postgres.js'
|
||||
description: 'Postgres.js Quickstart'
|
||||
breadcrumb: 'ORM Quickstarts'
|
||||
hideToc: true
|
||||
---
|
||||
|
||||
### Connecting with Postgres.js
|
||||
|
||||
[Postgres.js](https://github.com/porsager/postgres) is a full-featured Postgres client for Node.js and Deno.
|
||||
|
||||
<StepHikeCompact>
|
||||
|
||||
<StepHikeCompact.Step step={1}>
|
||||
|
||||
<StepHikeCompact.Details title="Install">
|
||||
|
||||
Install Postgres.js and related dependencies.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```shell
|
||||
npm i postgres
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
|
||||
<StepHikeCompact.Details title="Connect">
|
||||
|
||||
Create a `db.js` file with the connection details.
|
||||
|
||||
To get your connection details, go to your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database). Make sure `Use connection pooling` is enabled. Choose `Transaction Mode` if you're on a platform with transient connections, such as a serverless function, and `Session Mode` if you have a long-lived connection. Copy the URI and save it as the environment variable `DATABASE_URL`.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts
|
||||
// db.js
|
||||
import postgres from 'postgres'
|
||||
|
||||
const connectionString = process.env.DATABASE_URL
|
||||
const sql = postgres(connectionString)
|
||||
|
||||
export default sql
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
|
||||
<StepHikeCompact.Details title="Execute commands">
|
||||
|
||||
Use the connection to execute commands.
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
```ts
|
||||
import sql from './db.js'
|
||||
|
||||
async function getUsersOver(age) {
|
||||
const users = await sql`
|
||||
select name, age
|
||||
from users
|
||||
where age > ${ age }
|
||||
`
|
||||
// users = Result [{ name: "Walter", age: 80 }, { name: 'Murray', age: 68 }, ...]
|
||||
return users
|
||||
}
|
||||
```
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
450
apps/docs/content/guides/database/prisma.mdx
Normal file
@@ -0,0 +1,450 @@
|
||||
---
|
||||
id: 'prisma'
|
||||
title: 'Prisma'
|
||||
description: 'Prisma Quickstart'
|
||||
breadcrumb: 'ORM Quickstarts'
|
||||
hideToc: true
|
||||
---
|
||||
|
||||
This quickly shows how to connect your Prisma application to Supabase Postgres. If you encounter any problems, reference the [Prisma troubleshooting docs](/docs/guides/database/prisma-troubleshooting).
|
||||
|
||||
<Admonition type="note">
|
||||
|
||||
If you plan to solely use Prisma instead of the Supabase Data API (PostgREST), turn it off in the [API Settings](https://supabase.com/dashboard/project/_/settings/api).
|
||||
|
||||
</Admonition>
|
||||
|
||||
<StepHikeCompact>
|
||||
<StepHikeCompact.Step step={1}>
|
||||
<StepHikeCompact.Details title="Create a custom user for Prisma">
|
||||
- In the [SQL Editor](https://supabase.com/dashboard/project/_/sql/new), create a Prisma db-user with full privileges on the public schema.
|
||||
- This gives you better control over Prisma's access and makes it easier to monitor using Supabase tools like the [Query Performance Dashboard](https://supabase.com/dashboard/project/_/database/query-performance) and [Log Explorer](https://supabase.com/dashboard/project/_/logs/explorer).
|
||||
<Admonition type="note" label="password manager">
|
||||
|
||||
For security, consider using a [password generator](https://bitwarden.com/password-generator/) for the Prisma role.
|
||||
|
||||
</Admonition>
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
```sql
|
||||
-- Create custom user
|
||||
create user "prisma" with password 'custom_password' bypassrls createdb;
|
||||
|
||||
-- extend prisma's privileges to postgres (necessary to view changes in Dashboard)
|
||||
grant "prisma" to "postgres";
|
||||
|
||||
-- Grant it necessary permissions over the relevant schemas (public)
|
||||
grant usage on schema public to prisma;
|
||||
grant create on schema public to prisma;
|
||||
grant all on all tables in schema public to prisma;
|
||||
grant all on all routines in schema public to prisma;
|
||||
grant all on all sequences in schema public to prisma;
|
||||
alter default privileges for role postgres in schema public grant all on tables to prisma;
|
||||
alter default privileges for role postgres in schema public grant all on routines to prisma;
|
||||
alter default privileges for role postgres in schema public grant all on sequences to prisma;
|
||||
```
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={2}>
|
||||
<StepHikeCompact.Details title="Create a Prisma Project">
|
||||
Create a new prisma Project on your computer
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
Create a new directory
|
||||
```bash Terminal
|
||||
mkdir hello-prisma
|
||||
cd hello-prisma
|
||||
```
|
||||
|
||||
Initiate a new Prisma project
|
||||
<Tabs
|
||||
scrollable
|
||||
size="small"
|
||||
type="underlined"
|
||||
defaultActiveId="npm_initiate"
|
||||
queryGroup="initiate"
|
||||
>
|
||||
<TabPanel id="npm_initiate" label="npm">
|
||||
```bash
|
||||
npm init -y
|
||||
npm install prisma typescript ts-node @types/node --save-dev
|
||||
|
||||
npx tsc --init
|
||||
|
||||
npx prisma init
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="pnpm_initiate" label="pnpm">
|
||||
```bash
|
||||
pnpm init -y
|
||||
pnpm install prisma typescript ts-node @types/node --save-dev
|
||||
|
||||
pnpx tsc --init
|
||||
|
||||
pnpx prisma init
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="yarn_initiate" label="yarn">
|
||||
```bash
|
||||
yarn init -y
|
||||
yarn install prisma typescript ts-node @types/node --save-dev
|
||||
|
||||
yarn dlx tsc --init
|
||||
|
||||
yarn dlx prisma init
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="bun_initiate" label="bun">
|
||||
```bash
|
||||
bun init -y
|
||||
bun install prisma typescript ts-node @types/node --save-dev
|
||||
|
||||
bunx tsc --init
|
||||
|
||||
bunx prisma init
|
||||
```
|
||||
</TabPanel>
|
||||
</Tabs>
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={3}>
|
||||
<StepHikeCompact.Details title="Add your connection information to your .env file">
|
||||
- Visit the [Database Settings](https://supabase.com/dashboard/project/_/settings/database)
|
||||

|
||||
- Find your Supavisor Session Mode string. It should end with 5432. It will be used in your `.env` file.
|
||||
<Admonition type="note">
|
||||
If you're in an [IPv6 environment](https://github.com/orgs/supabase/discussions/27034) or have the IPv4 Add-On, you can use the direct connection string instead of Supavisor in Session mode.
|
||||
</Admonition>
|
||||
|
||||
- If you plan on deploying Prisma to a serverless or auto-scaling environment, you'll also need your Supavisor transaction mode string.
|
||||

|
||||
- The string is identical to the session mode string but uses port 6543 at the end.
|
||||
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
<Tabs>
|
||||
<TabPanel id="serverful" label="server-based deployments">
|
||||
In your .env file, set the DATABASE_URL variable to your connection string
|
||||
```text .env
|
||||
# Used for Prisma Migrations and within your application
|
||||
DATABASE_URL="postgres://[DB-USER].[PROJECT-REF]:[YOUR-PASSWORD]@aws-0-us-east-1.pooler.supabase.com:5432/postgres"
|
||||
```
|
||||
|
||||
Change your string's `[DB-USER]` to `prisma` and add the password you created in step 1
|
||||
```md
|
||||
postgres://prisma.[PROJECT-REF]...
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="serverless" label="serverless deployments">
|
||||
|
||||
Assign the connection string for Supavisor Transaction Mode (using port 6543) to the DATABASE_URL variable in your .env file. Make sure to append "pgbouncer=true" to the end of the string to work with Supavisor.
|
||||
|
||||
Next, create a DIRECT_URL variable in your .env file and assign the connection string that ends with port 5432 to it.
|
||||
|
||||
```text .env # Used in your application (use transaction mode)
|
||||
DATABASE_URL="postgres://[DB-USER].[PROJECT-REF]:[YOUR-PASSWORD]@aws-0-us-east-1.pooler.supabase.com:6543/postgres?pgbouncer=true"
|
||||
|
||||
# Used for Prisma Migrations (use session mode or direct connection)
|
||||
DIRECT_URL="postgres://[DB-USER].[PROJECT-REF]:[YOUR-PASSWORD]@aws-0-us-east-1.pooler.supabase.com:5432/postgres"
|
||||
```
|
||||
|
||||
Change both your strings' `[DB-USER]` to `prisma` and then add the password created in step 1
|
||||
```md
|
||||
postgres://prisma.[PROJECT-REF]...
|
||||
```
|
||||
|
||||
In your schema.prisma file, edit your datasource db configs to reference your DIRECT_URL
|
||||
```text schema.prisma
|
||||
datasource db {
|
||||
provider = "postgresql"
|
||||
url = env("DATABASE_URL")
|
||||
directUrl = env("DIRECT_URL")
|
||||
}
|
||||
```
|
||||
|
||||
|
||||
</TabPanel>
|
||||
|
||||
</Tabs>
|
||||
|
||||
|
||||
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
<StepHikeCompact.Step step={5}>
|
||||
<StepHikeCompact.Details title="Create your migrations">
|
||||
|
||||
If you have already modified your Supabase database, synchronize it with your migration file. Otherwise create new tables for your database
|
||||
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
|
||||
<Tabs>
|
||||
|
||||
<TabPanel id="new-projects" label="New Projects">
|
||||
Create new tables in your prisma.schema file
|
||||
|
||||
```ts prisma/schema.prisma
|
||||
model Post {
|
||||
id Int @id @default(autoincrement())
|
||||
title String
|
||||
content String?
|
||||
published Boolean @default(false)
|
||||
author User? @relation(fields: [authorId], references: [id])
|
||||
authorId Int?
|
||||
}
|
||||
|
||||
model User {
|
||||
id Int @id @default(autoincrement())
|
||||
email String @unique
|
||||
name String?
|
||||
posts Post[]
|
||||
}
|
||||
```
|
||||
commit your migration
|
||||
|
||||
<Tabs
|
||||
scrollable
|
||||
size="small"
|
||||
type="underlined"
|
||||
defaultActiveId="npm_migrate"
|
||||
queryGroup="migrate"
|
||||
>
|
||||
<TabPanel id="npm_migrate" label="npm">
|
||||
```bash
|
||||
npx prisma migrate dev --name first_prisma_migration
|
||||
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="pnpm_migrate" label="pnpm">
|
||||
```bash
|
||||
pnpx prisma migrate dev --name first_prisma_migration
|
||||
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="yarn_migrate" label="yarn">
|
||||
```bash
|
||||
yarn dlx prisma migrate dev --name first_prisma_migration
|
||||
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="bun_migrate" label="bun">
|
||||
```bash
|
||||
bunx prisma migrate dev --name first_prisma_migration
|
||||
|
||||
```
|
||||
</TabPanel>
|
||||
</Tabs>
|
||||
|
||||
</TabPanel>
|
||||
|
||||
<TabPanel id="established-projects" label="Populated Projects">
|
||||
Synchronize changes from your project:
|
||||
<Tabs
|
||||
scrollable
|
||||
size="small"
|
||||
type="underlined"
|
||||
defaultActiveId="npm_sync"
|
||||
queryGroup="sync"
|
||||
>
|
||||
<TabPanel id="npm_sync" label="npm">
|
||||
```bash
|
||||
npx prisma db pull
|
||||
```
|
||||
|
||||
Create a migraton file
|
||||
```bash
|
||||
mkdir -p prisma/migrations/0_init_supabase
|
||||
```
|
||||
|
||||
Synchronize the migrations
|
||||
```bash
|
||||
npx prisma migrate diff \
|
||||
--from-empty \
|
||||
--to-schema-datamodel prisma/schema.prisma \
|
||||
--script > prisma/migrations/0_init_supabase/migration.sql
|
||||
```
|
||||
<Admonition type="tip" label="conflict management">
|
||||
If there are any conflicts, reference [Prisma's official doc](https://www.prisma.io/docs/orm/prisma-migrate/getting-started#work-around-features-not-supported-by-prisma-schema-language) or the [trouble shooting guide](/docs/guides/database/prisma-troubleshooting) for more details
|
||||
</Admonition>
|
||||
|
||||
```bash
|
||||
npx prisma migrate resolve --applied 0_init_supabase
|
||||
```
|
||||
</TabPanel>
|
||||
|
||||
<TabPanel id="pnpm_sync" label="pnpm">
|
||||
```bash
|
||||
pnpx prisma db pull
|
||||
```
|
||||
|
||||
Create a migraton file
|
||||
```bash
|
||||
mkdir -p prisma/migrations/0_init_supabase
|
||||
```
|
||||
|
||||
Synchronize the migrations
|
||||
```bash
|
||||
pnpx prisma migrate diff \
|
||||
--from-empty \
|
||||
--to-schema-datamodel prisma/schema.prisma \
|
||||
--script > prisma/migrations/0_init_supabase/migration.sql
|
||||
```
|
||||
<Admonition type="note" label="conflict management">
|
||||
If there are any conflicts, reference [Prisma's official doc](https://www.prisma.io/docs/orm/prisma-migrate/getting-started#work-around-features-not-supported-by-prisma-schema-language) or the [trouble shooting guide](/docs/guides/database/prisma-troubleshooting) for more details
|
||||
</Admonition>
|
||||
|
||||
```bash
|
||||
pnpx prisma migrate resolve --applied 0_init_supabase
|
||||
```
|
||||
</TabPanel>
|
||||
|
||||
<TabPanel id="yarn_sync" label="yarn">
|
||||
```bash
|
||||
yarn dlx prisma db pull
|
||||
```
|
||||
|
||||
Create a migraton file
|
||||
```bash
|
||||
mkdir -p prisma/migrations/0_init_supabase
|
||||
```
|
||||
|
||||
Synchronize the migrations
|
||||
```bash
|
||||
yarn dlx prisma migrate diff \
|
||||
--from-empty \
|
||||
--to-schema-datamodel prisma/schema.prisma \
|
||||
--script > prisma/migrations/0_init_supabase/migration.sql
|
||||
```
|
||||
<Admonition type="note" label="conflict management">
|
||||
If there are any conflicts, reference [Prisma's official doc](https://www.prisma.io/docs/orm/prisma-migrate/getting-started#work-around-features-not-supported-by-prisma-schema-language) or the [trouble shooting guide](/docs/guides/database/prisma-troubleshooting) for more details
|
||||
</Admonition>
|
||||
|
||||
```bash
|
||||
yarn dlx prisma migrate resolve --applied 0_init_supabase
|
||||
```
|
||||
</TabPanel>
|
||||
|
||||
<TabPanel id="bun_sync" label="bun">
|
||||
```bash
|
||||
bunx prisma db pull
|
||||
```
|
||||
|
||||
Create a migraton file
|
||||
```bash
|
||||
mkdir -p prisma/migrations/0_init_supabase
|
||||
```
|
||||
|
||||
Synchronize the migrations
|
||||
```bash
|
||||
bunx prisma migrate diff \
|
||||
--from-empty \
|
||||
--to-schema-datamodel prisma/schema.prisma \
|
||||
--script > prisma/migrations/0_init_supabase/migration.sql
|
||||
```
|
||||
<Admonition type="note" label="conflict management">
|
||||
If there are any conflicts, reference [Prisma's official doc](https://www.prisma.io/docs/orm/prisma-migrate/getting-started#work-around-features-not-supported-by-prisma-schema-language) or the [trouble shooting guide](/docs/guides/database/prisma-troubleshooting) for more details
|
||||
</Admonition>
|
||||
|
||||
```bash
|
||||
bunx prisma migrate resolve --applied 0_init_supabase
|
||||
```
|
||||
</TabPanel>
|
||||
</Tabs>
|
||||
|
||||
</TabPanel>
|
||||
|
||||
</Tabs>
|
||||
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
<StepHikeCompact.Step step={6}>
|
||||
<StepHikeCompact.Details title="Install the prisma client">
|
||||
Install the prisma client and generate its model
|
||||
</StepHikeCompact.Details>
|
||||
|
||||
<StepHikeCompact.Code>
|
||||
<Tabs
|
||||
scrollable
|
||||
size="small"
|
||||
type="underlined"
|
||||
defaultActiveId="npm_client"
|
||||
queryGroup="client"
|
||||
>
|
||||
<TabPanel id="npm_client" label="npm">
|
||||
```sh
|
||||
npm install @prisma/client
|
||||
npx prisma generate
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="pnpm_client" label="pnpm">
|
||||
```sh
|
||||
pnpm install @prisma/client
|
||||
pnpx prisma generate
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="yarn_client" label="yarn">
|
||||
```sh
|
||||
yarn install @prisma/client
|
||||
yarn dlx prisma generate
|
||||
```
|
||||
</TabPanel>
|
||||
<TabPanel id="bun_client" label="bun">
|
||||
```sh
|
||||
bun install @prisma/client
|
||||
bunx prisma generate
|
||||
```
|
||||
</TabPanel>
|
||||
</Tabs>
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
<StepHikeCompact.Step step={7}>
|
||||
<StepHikeCompact.Details title="Test your API">
|
||||
Create a index.ts file and run it to test your connection
|
||||
</StepHikeCompact.Details>
|
||||
<StepHikeCompact.Code>
|
||||
```ts index.ts
|
||||
const { PrismaClient } = require('@prisma/client');
|
||||
|
||||
const prisma = new PrismaClient();
|
||||
|
||||
async function main() {
|
||||
//change to reference a table in your schema
|
||||
const val = await prisma.<SOME_TABLE_NAME>.findMany({
|
||||
take: 10,
|
||||
});
|
||||
console.log(val);
|
||||
}
|
||||
|
||||
main()
|
||||
.then(async () => {
|
||||
await prisma.$disconnect();
|
||||
})
|
||||
.catch(async (e) => {
|
||||
console.error(e);
|
||||
await prisma.$disconnect();
|
||||
process.exit(1);
|
||||
});
|
||||
|
||||
```
|
||||
</StepHikeCompact.Code>
|
||||
|
||||
</StepHikeCompact.Step>
|
||||
|
||||
</StepHikeCompact>
|
||||
@@ -0,0 +1,246 @@
|
||||
---
|
||||
id: 'prisma-troubleshooting'
|
||||
title: 'Troubleshooting prisma errors'
|
||||
description: 'Prisma error troubleshooting'
|
||||
breadcrumb: 'ORM Quickstarts'
|
||||
---
|
||||
|
||||
This guide addresses common Prisma errors that you might encounter while using Supabase.
|
||||
|
||||
<Admonition type="note">
|
||||
|
||||
A full list of errors can be found in [Prisma's official docs](https://www.prisma.io/docs/orm/reference/error-reference).
|
||||
|
||||
</Admonition>
|
||||
|
||||
## Understanding connection string parameters: [#start]
|
||||
|
||||
Unlike other libraries, Prisma lets you configure [its settings](https://www.prisma.io/docs/orm/overview/databases/postgresql#arguments) through special options appended to your connection string.
|
||||
|
||||
These options, called "query parameters," can be used to address specific errors.
|
||||
|
||||
```md
|
||||
# Example of query parameters
|
||||
|
||||
connection_string.../postgres?KEY1=VALUE&KEY2=VALUE&KEY3=VALUE
|
||||
```
|
||||
|
||||
# Errors
|
||||
|
||||
## ... prepared statement already exists
|
||||
|
||||
Supavisor in transaction mode (port 6543) does not support [prepared statements](https://www.postgresql.org/docs/current/sql-prepare.html), which Prisma will try to create in the background.
|
||||
|
||||
### Solution: [#solution-prepared-statement-exists]
|
||||
|
||||
- Add `pgbouncer=true` to the connection string. This turns off prepared statements in Prisma.
|
||||
|
||||
```md
|
||||
.../postgres?pgbouncer=true
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Can't reach database server at:
|
||||
|
||||
Prisma couldn't establish a connection with Postgres or Supavisor before the timeout
|
||||
|
||||
### Possible causes: [#possible-causes-cant-reach-database-server-at]
|
||||
|
||||
- **Database overload**: The database server is under heavy load, causing Prisma to struggle to connect.
|
||||
- **Malformed connection string**: The connection string used by Prisma is incorrect or incomplete.
|
||||
- **Transient network issues**: Temporary network problems are disrupting the connection.
|
||||
|
||||
### Solutions: [#solution-cant-reach-database-server-at]
|
||||
|
||||
- **Check database health**: Use the [Reports Dashboard](https://supabase.com/dashboard/project/_/reports/database) to monitor CPU, memory, and I/O usage. If the database is overloaded, consider increasing your [compute size](https://supabase.com/docs/guides/platform/compute-add-ons) or [optimizing your queries](https://supabase.com/docs/guides/database/query-optimization).
|
||||
- **Verify connection string**: Double-check the connection string in your Prisma configuration to ensure it matches one in your [Database Settings](https://supabase.com/dashboard/project/_/settings/database).
|
||||
- **Increase connection timeout**: Try increasing the `connect_timeout` parameter in your Prisma configuration to give it more time to establish a connection.
|
||||
|
||||
```md
|
||||
.../postgres?connect_timeout=30
|
||||
```
|
||||
|
||||
---
|
||||
|
||||
## Timed out fetching a new connection from the connection pool:
|
||||
|
||||
Prisma is unable to allocate connections to pending queries fast enough to meet demand.
|
||||
|
||||
### Possible causes: [#possible-causes-timed-out-fetching-a-new-connection]
|
||||
|
||||
- **Overwhelmed server**: The server hosting Prisma is under heavy load, limiting its ability to manage connections. By default, Prisma will create the default `2 * num_cpus / 2` worth of connections. A common cause for server strain is increasing the `connection_limit` significantly past the default.
|
||||
- **Insufficient pool size**: The Supavisor pooler does not have enough connections available to quickly satisfy Prisma's requests.
|
||||
- **Slow queries**: Prisma's queries are taking too long to execute, preventing it from releasing connections for reuse.
|
||||
|
||||
### Solutions: [#solution-timed-out-fetching-a-new-connection]
|
||||
|
||||
- **Increase the pool timeout**: Increase the `pool_timeout` parameter in your Prisma configuration to give the pooler more time to allocate connections.
|
||||
- **Reduce the connection limit**: If you've explicitly increased the `connection_limit` parameter in your Prisma configuration, try reducing it to a more reasonable value.
|
||||
- **Increase pool size**: If you are connecting with Supavisor, try increasing the pool size in the [Database Settings](https://supabase.com/dashboard/project/_/settings/database).
|
||||
- **Optimize queries**: [Improve the efficiency of your queries](https://supabase.com/docs/guides/database/query-optimization) to reduce execution time.
|
||||
- **Increase compute size**: Like the preceding option, this is a strategy to reduce query execution time.
|
||||
|
||||
---
|
||||
|
||||
## Server has closed the connection
|
||||
|
||||
According to this [GitHub Issue for Prisma](https://github.com/prisma/prisma/discussions/7389), this error may be related to large return values for queries. It may also be caused by significant database strain.
|
||||
|
||||
### Solutions: [#solution-server-has-closed-the-connection]
|
||||
|
||||
- **Limit row return sizes**: Try to limit the total amount of rows returned for particularly large requests.
|
||||
- **Minimize database strain**:Check the Reports Page for database strain. If there is obvious strain, consider [optimizing](https://supabase.com/docs/guides/database/query-optimization) or increasing compute size
|
||||
|
||||
---
|
||||
|
||||
## Drift detected: Your database schema is not in sync with your migration history
|
||||
|
||||
Prisma relies on migration files to ensure your database aligns with Prisma's model. External schema changes are detected as "drift", which Prisma will try to overwrite, potentially causing data loss.
|
||||
|
||||
### Possible causes: [#possible-causes-your-database-schema-is-not-in-sync]
|
||||
|
||||
- **Supabase Managed Schemas**: Supabase may update managed schemas like auth and storage to introduce new features. Granting Prisma access to these schemas can lead to drift during updates.
|
||||
- **External Schema Modifications**: Your team or another tool might have modified the database schema outside of Prisma, causing drift.
|
||||
|
||||
### Solution: [#solution-your-database-schema-is-not-in-sync]
|
||||
|
||||
- **Baselining migrations**: [baselining](https://www.prisma.io/docs/orm/prisma-migrate/workflows/baselining) re-syncs Prisma by capturing the current database schema as the starting point for future migrations.
|
||||
|
||||
---
|
||||
|
||||
## Max client connections reached
|
||||
|
||||
Postgres or Supavisor rejected a request for more connections
|
||||
|
||||
### Possible causes:[#possible-causes-max-client-connections-reached]
|
||||
|
||||
- **When working in transaction mode (port 6543):** The error "Max client connections reached" occurs when clients try to form more connections with the pooler than it can support.
|
||||
- **When working in session mode (port 5432):** The max amount of clients is restricted to the "Pool Size" value in the [Database Settings](https://supabase.com/dashboard/project/_/settings/database). If the "Pool Size" is set to 15, even if the pooler can handle 200 client connections, it will still be effectively capped at 15 for each unique ["database-role+database" combination](https://github.com/orgs/supabase/discussions/21566).
|
||||
- **When working with direct connections**: Postgres is already servicing the max amount of connections
|
||||
|
||||
### Solutions [#solutions-causes-max-client-connections-reached]
|
||||
|
||||
- **Transaction Mode for serverless apps**: If you are using serverless functions (Supabase Edge, Vercel, AWS Lambda), switch to transaction mode (port 6543). It handles more connections than session mode or direct connections.
|
||||
- **Reduce the number of Prisma connections**: A single client-server can establish multiple connections with a pooler. Typically, serverless setups do not need many connections. Starting with fewer, like five or three, or even just one, is often sufficient. In serverless setups, begin with `connection_limit=1`, increasing cautiously if needed to avoid maxing out connections.
|
||||
- **Increase pool size**: If you are connecting with Supavisor, try increasing the pool size in the [Database Settings](https://supabase.com/dashboard/project/_/settings/database).
|
||||
- **Disconnect appropriately**: Close Prisma connections when they are no longer needed.
|
||||
- **Decrease query time**: Reduce query complexity or add [strategic indexes](https://supabase.com/docs/guides/database/postgres/indexes) to your tables to speed up queries.
|
||||
- **Increase compute size**: Sometimes the best option is to increase your compute size, which also increases your max client size and query execution speed
|
||||
|
||||
---
|
||||
|
||||
## Cross schema references are only allowed when the target schema is listed in the schemas property of your data-source
|
||||
|
||||
A Prisma migration is referencing a schema it is not permitted to manage.
|
||||
|
||||
### Possible causes: [#possible-causes-cross-schema-references]
|
||||
|
||||
- A migration references a schema that Prisma is not permitted to manage
|
||||
|
||||
### Solutions: [#solutions-cross-schema-references]
|
||||
|
||||
- Multi-Schema support: If the external schema isn't Supabase managed, modify your `prisma.schema` file to enable the multi-Schema preview
|
||||
|
||||
```ts prisma.schema
|
||||
generator client {
|
||||
provider = "prisma-client-js"
|
||||
previewFeatures = ["multiSchema"] //Add line
|
||||
}
|
||||
|
||||
datasource db {
|
||||
provider = "postgresql"
|
||||
url = env("DATABASE_URL")
|
||||
directUrl = env("DIRECT_URL")
|
||||
schemas = ["public", "other_schema"] //list out relevant schemas
|
||||
}
|
||||
```
|
||||
|
||||
- Supabase managed schemas: Schemas managed by Supabase, such as `auth` and `storage`, may be changed to support new features. Referencing these schemas directly will cause schema drift in the future. It is best to remove references to these schemas from your migrations.
|
||||
|
||||
An alternative strategy to reference these tables is to duplicate values into Prisma managed table with triggers. Below is an example for duplicating values from `auth.users` into a table called `profiles`.
|
||||
|
||||
<details>
|
||||
<summary>Show/Hide Details</summary>
|
||||
|
||||
```sql table_in_public
|
||||
-- Create the 'profiles' table in the 'public' schema
|
||||
create table public.profiles (
|
||||
id uuid primary key, -- 'id' is a UUID and the primary key for the table
|
||||
email varchar(256) -- 'email' is a variable character field with a maximum length of 256 characters
|
||||
);
|
||||
```
|
||||
|
||||
```sql trigger_on_insert
|
||||
-- Function to handle the insertion of a new user into the 'profiles' table
|
||||
create function public.handle_new_user()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
security definer set search_path = ''
|
||||
as $$
|
||||
begin
|
||||
|
||||
-- Insert the new user's data into the 'profiles' table
|
||||
insert into public.profiles (id, email)
|
||||
values (new.id, new.email);
|
||||
|
||||
return new; -- Return the new record
|
||||
end;
|
||||
$$;
|
||||
```
|
||||
|
||||
```sql trigger_on_update
|
||||
-- Function to handle the updating of a user's information in the 'profiles' table
|
||||
create function public.update_user()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
security definer set search_path = ''
|
||||
as
|
||||
$$
|
||||
begin
|
||||
-- Update the user's data in the 'profiles' table
|
||||
update public.profiles
|
||||
set email = new.email -- Update the 'email' field
|
||||
where id = new.id; -- Match the 'id' field with the new record
|
||||
|
||||
return new; -- Return the new record
|
||||
end;
|
||||
$$;
|
||||
```
|
||||
|
||||
```sql trigger_on_delete
|
||||
-- Function to handle the deletion of a user from the 'profiles' table
|
||||
create function public.delete_user()
|
||||
returns trigger
|
||||
language plpgsql
|
||||
security definer set search_path = ''
|
||||
as
|
||||
$$
|
||||
begin
|
||||
-- Delete the user's data from the 'profiles' table
|
||||
delete from public.profiles
|
||||
where id = old.id; -- Match the 'id' field with the old record
|
||||
|
||||
return old; -- Return the old record
|
||||
end;
|
||||
$$;
|
||||
```
|
||||
|
||||
```sql triggers_on_auth
|
||||
-- Trigger to run 'handle_new_user' function after a new user is inserted into 'auth.users' table
|
||||
create trigger on_auth_user_created
|
||||
after insert on auth.users
|
||||
for each row execute procedure public.handle_new_user();
|
||||
|
||||
-- Trigger to run 'update_user' function after a user is updated in the 'auth.users' table
|
||||
create trigger on_auth_user_updated
|
||||
after update on auth.users
|
||||
for each row execute procedure public.update_user();
|
||||
|
||||
-- Trigger to run 'delete_user' function after a user is deleted from the 'auth.users' table
|
||||
create trigger on_auth_user_deleted
|
||||
after delete on auth.users
|
||||
for each row execute procedure public.delete_user();
|
||||
```
|
||||
|
||||
</details>
|
||||
24
apps/docs/content/guides/database/psql.mdx
Normal file
@@ -0,0 +1,24 @@
|
||||
---
|
||||
id: 'psql'
|
||||
title: 'Connecting with PSQL'
|
||||
breadcrumb: 'GUI Quickstarts'
|
||||
hideToc: true
|
||||
---
|
||||
|
||||
[`psql`](https://www.postgresql.org/docs/current/app-psql.html) is a command-line tool that comes with Postgres.
|
||||
|
||||
## Connecting with SSL
|
||||
|
||||
You should connect to your database using SSL wherever possible, to prevent snooping and man-in-the-middle attacks.
|
||||
|
||||
You can obtain your connection info and Server root certificate from your application's dashboard:
|
||||
|
||||

|
||||
|
||||
Download your [SSL certificate](#connecting-with-ssl) to `/path/to/prod-supabase.cer`.
|
||||
|
||||
Find your connection settings. Go to your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database) and make sure `Use connection pooling` is checked. Change the connection mode to `Session`, and copy the parameters into the connection string:
|
||||
|
||||
```shell
|
||||
psql "sslmode=verify-full sslrootcert=/path/to/prod-supabase.cer host=[CLOUD_PROVIDER]-0-[REGION].pooler.supabase.com dbname=postgres user=postgres.[PROJECT_REF]"
|
||||
```
|
||||
16
apps/docs/content/guides/database/supavisor.mdx
Normal file
@@ -0,0 +1,16 @@
|
||||
---
|
||||
title: Supavisor
|
||||
subtitle: Troubleshooting Supavisor errors
|
||||
---
|
||||
|
||||
Supavisor logs are available under [Pooler Logs](/dashboard/project/_/logs/pooler-logs) in the Dashboard. The following are common errors and their solutions:
|
||||
|
||||
| Error Type | Description | Resolution Link |
|
||||
| ------------------------------------------------------------------------ | --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | ----------------------------------------------------------------------------------- |
|
||||
| Max client connections reached | This error happens when the number of connections to Supavisor is more than [the allowed limit of your compute add-on](https://supabase.com/docs/guides/platform/compute-add-ons). | Follow this [guide](https://github.com/orgs/supabase/discussions/22305) to resolve. |
|
||||
| Connection failed \{:error, :eaddrnotavail} to 'db.xxx.supabase.co':5432 | Supavisor cannot connect to the customer database. This is usually caused if the target database is unable to respond. | N/A |
|
||||
| Connection failed \{:error, :nxdomain} to 'db.xxx.supabase.co':5432 | Supavisor cannot connect to the customer database. This is usually caused if the target database is unable to respond. | N/A |
|
||||
| Connection closed when state was authentication | This error happens when either the database doesn’t exist or if the user doesn't have the right credentials. | N/A |
|
||||
| Subscribe error: \{:error, :worker_not_found} | This log event is emitted when the client tries to connect to the database, but Supavisor does not have the necessary information to route the connection. Try reconnecting to the database as it can take some time for the project information to propagate to Supavisor. | N/A |
|
||||
| Subscribe error: \{:error, \{:badrpc, \{:error, \{:erpc, :timeout}}}} | This is a timeout error when the communication between different Supavisor nodes takes longer than expected. Try reconnecting to the database. | N/A |
|
||||
| Terminating with reason :client_termination when state was :busy | This error happens when the client terminates the connection before the connection with the database is completed. | N/A |
|
||||
@@ -4,43 +4,94 @@ description: 'Attach an IPv4 address to your database'
|
||||
subtitle: 'Attach an IPv4 address to your database'
|
||||
---
|
||||
|
||||
The add-on is $4 per month - we're passing on the AWS costs to you. The add-on is available for all paid plans.
|
||||
The Supabase IPv4 add-on provides a dedicated IPv4 address for your Postgres database connection. It can be configured in the [Add-Ons Settings](/dashboard/project/_/settings/addons).
|
||||
|
||||
## When is this add-on required?
|
||||
## Understanding IP addresses
|
||||
|
||||
This add-on is not required if any of these conditions are met
|
||||
The Internet Protocol (IP) addresses devices on the internet. There are two main versions:
|
||||
|
||||
- you are only connecting to the database via Supavisor, our connection pooler, or via any of our client libraries.
|
||||
- If you are connecting to the database directly and the network from which you are connecting to the database supports IPv6 addresses.
|
||||
- **IPv4**: The older version, with a limited address space.
|
||||
- **IPv6**: The newer version, offering a much larger address space and the future-proof option.
|
||||
|
||||
This add-on is only required if you are connecting to the database directly from an IPv6 incompatible network.
|
||||
## When you need the IPv4 add-on:
|
||||
|
||||
<Admonition type="note" label="Add-on has no impact on PGBouncer removal">
|
||||
- When using the direct connection string in an IPv6-incompatible network instead of Supavisor or client libraries.
|
||||
- When you need a dedicated IP address for your direct connection string
|
||||
|
||||
When you purchase this add-on, your project won't be migrated to IPv6. PGBouncer will still be removed for the project according to the timeline mentioned in [this discussion](https://github.com/orgs/supabase/discussions/17817);
|
||||
## Enabling the IPv4 add-on
|
||||
|
||||
</Admonition>
|
||||
You can enable the IPv4 add-on in your project's [add-ons settings](/dashboard/project/_/settings/addons). Enabling the add-on may briefly disable your database during reconfiguration.
|
||||
|
||||
## Enabling the add-on
|
||||
## Read replicas and IPv4 add-on
|
||||
|
||||
You can enable the IPv4 add-on in your project [add-on settings](https://supabase.com/dashboard/project/_/settings/addons) page.
|
||||
When using the add-on, each database (including read replicas) receives an IPv4 address. Each replica adds to the total IPv4 cost.
|
||||
|
||||
<Admonition type="caution" label="Downtime when add-on is toggled.">
|
||||
Note that there might be some downtime when toggling the add-on since some DNS clients might have
|
||||
cached the old DNS entry and it might take some time for the updated DNS entry to be picked up.
|
||||
Generally, this should be less than a minute.
|
||||
</Admonition>
|
||||
## Changes and updates
|
||||
|
||||
## Read Replicas
|
||||
- While the IPv4 address generally remains the same, actions like pausing/unpausing the project or enabling/disabling the add-on can lead to a new IPv4 address.
|
||||
|
||||
When the IPv4 add-on is enabled, an IPv4 address is provisioned for each database in your project.
|
||||
## Supabase and IPv6 compatibility
|
||||
|
||||
By default, this is only the Primary database for your project. If [Read replicas](/docs/guides/platform/read-replicas) are being used, each replica also gets its own IPv4 address, with a corresponding $4 charge.
|
||||
By default, Supabase Postgres use IPv6 addresses. If your system doesn't support IPv6, you have the following options:
|
||||
|
||||
## Caveats
|
||||
1. **Supavisor Connection Strings**: The Supavisor connection strings are IPv4-compatible alternatives to direct connections
|
||||
2. **Supabase Client Libraries**: These libraries are compatible with IPv4
|
||||
3. **Dedicated IPv4 Add-On (Pro Plans+)**: For a guaranteed IPv4 and static database address for the direct connection, enable this paid add-on.
|
||||
|
||||
For regular use-cases like a restart or compute size changes, the IPv4 address remains unchanged.
|
||||
However, there are cases where maintaining the same IPv4 address isn't guaranteed. These include:
|
||||
### Checking your network IPv6 support
|
||||
|
||||
- If the project gets paused and unpaused
|
||||
- If the add-on gets removed and added again
|
||||
Most services are IPv6 compatible, but some exceptions exist (listed below). To verify your personal network supports it, run this command on your server:
|
||||
|
||||
```sh
|
||||
curl -6 https://ifconfig.co/ip
|
||||
```
|
||||
|
||||
If it returns an IPv6 address then your system is compatible. An example IPv6 address might look like: `2a05:d014:1c06:5f0c:d7a9:8616:bee2:30df`.
|
||||
|
||||
### Checking platforms for IPv6 support:
|
||||
|
||||
The majority of services are IPv6 compatible. However, there are a few prominent ones that only accept IPv4 connections:
|
||||
|
||||
- [Retool](https://retool.com/)
|
||||
- [Vercel](https://vercel.com/)
|
||||
- [GitHub Actions](https://docs.github.com/en/actions)
|
||||
- [Render](https://render.com/)
|
||||
|
||||
## Finding your database's IP address
|
||||
|
||||
Use an IP lookup website or this command (replace `<PROJECT_REF>`):
|
||||
|
||||
```sh
|
||||
nslookup db.<PROJECT_REF>.supabase.co
|
||||
```
|
||||
|
||||
## Identifying your connections
|
||||
|
||||
The pooler and direct connection strings can be found in the [database settings](https://supabase.com/dashboard/project/_/settings/database):
|
||||
|
||||
#### Direct connection
|
||||
|
||||
IPv6 unless IPv4 Add-On is enabled
|
||||
|
||||
```sh
|
||||
# Example direct connection string
|
||||
postgresql://postgres:[YOUR-PASSWORD]@db.ajrbwkcuthywfihaarmflo.supabase.co:5432/postgres
|
||||
```
|
||||
|
||||
#### Supavisor in transaction mode (port 6543)
|
||||
|
||||
Always uses an IPv4 address
|
||||
|
||||
```sh
|
||||
# Example transaction string
|
||||
postgresql://postgres.ajrbwkcuthywddfihrmflo:[YOUR-PASSWORD]@aws-0-us-east-1.pooler.supabase.com:6543/postgres
|
||||
```
|
||||
|
||||
#### Supavisor in session mode (port 5432)
|
||||
|
||||
Always uses an IPv4 address
|
||||
|
||||
```sh
|
||||
# Example session string
|
||||
postgresql://postgres.ajrbwkcuthywfddihrmflo:[YOUR-PASSWORD]@aws-0-us-east-1.pooler.supabase.com:5432/postgres
|
||||
```
|
||||
|
||||
BIN
apps/docs/public/img/database/grafana-connections.png
Normal file
|
After Width: | Height: | Size: 34 KiB |
BIN
apps/docs/public/img/database/pool-size.png
Normal file
|
After Width: | Height: | Size: 187 KiB |
BIN
apps/docs/public/img/database/session-mode.png
Normal file
|
After Width: | Height: | Size: 105 KiB |
BIN
apps/docs/public/img/database/transaction-mode.png
Normal file
|
After Width: | Height: | Size: 92 KiB |
|
After Width: | Height: | Size: 71 KiB |
|
After Width: | Height: | Size: 630 KiB |
|
After Width: | Height: | Size: 427 KiB |
|
After Width: | Height: | Size: 394 KiB |
|
After Width: | Height: | Size: 893 KiB |
|
After Width: | Height: | Size: 95 KiB |
|
After Width: | Height: | Size: 377 KiB |
@@ -1545,6 +1545,75 @@ module.exports = [
|
||||
source: '/projects',
|
||||
destination: 'https://supabase.com/dashboard/projects',
|
||||
},
|
||||
// Reorganizing pooler docs:-----------------------------
|
||||
|
||||
//external libraries
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#integrations',
|
||||
destination: '/docs/guides/database/connecting-to-postgres#quickstart-connection-guides',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#connecting-with-drizzle',
|
||||
destination: '/docs/guides/database/drizzle',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#connecting-with-prisma',
|
||||
destination: '/docs/guides/database/prisma',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#connecting-with-postgresjs',
|
||||
destination: '/docs/guides/database/postgres-js',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#connecting-with-pgadmin',
|
||||
destination: '/docs/guides/database/pgadmin',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#connecting-with-psql',
|
||||
destination: '/docs/guides/database/psql',
|
||||
},
|
||||
|
||||
// pooling
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#connection-pooler',
|
||||
destination: '/docs/guides/database/connecting-to-postgres#connection-pooling-in-depth',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#troubleshooting-supavisor',
|
||||
destination: '/docs/guides/database/supavisor',
|
||||
},
|
||||
|
||||
//IPv4/IPv6
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#finding-your-database-hostname',
|
||||
destination: '/docs/guides/platform/ipv4-address#finding-your-databases-ip-address',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#managing-your-ip-address',
|
||||
destination: '/docs/guides/platform/ipv4-address#supabase-and-ipv6-compatibility',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#ipv6-address',
|
||||
destination: '/docs/guides/platform/ipv4-address#supabase-and-ipv6-compatibility',
|
||||
},
|
||||
{
|
||||
permanent: true,
|
||||
source: '/docs/guides/database/connecting-to-postgres#ipv4-address',
|
||||
destination: '/docs/guides/platform/ipv4-address',
|
||||
},
|
||||
//--------------------------------------------------------
|
||||
|
||||
// START docs 2.0, moving pages in to structure
|
||||
{
|
||||
permanent: true,
|
||||
|
||||
@@ -1,5 +1,6 @@
|
||||
APIs
|
||||
[Aa]uth
|
||||
[Bb]aselining
|
||||
Berri
|
||||
[Cc]hatbots?
|
||||
ChatGPT
|
||||
@@ -9,6 +10,7 @@ Colab
|
||||
[Cc]onfigs?
|
||||
CPUs?
|
||||
CTEs?
|
||||
DBeaver
|
||||
[Dd]eclarative(ly)?
|
||||
[Dd]eduplicat(e|ion)
|
||||
[Dd]eeplinks?
|
||||
@@ -49,6 +51,7 @@ OpenAI
|
||||
[Pp]erformant
|
||||
pg_plan_filter
|
||||
PGAudit
|
||||
pgAdmin
|
||||
PGroonga
|
||||
pgvector
|
||||
Pinecone
|
||||
@@ -68,6 +71,8 @@ RESTful
|
||||
Roboflow
|
||||
[Ss]crollable
|
||||
[Ss]erializ(e|ed|es|ing)
|
||||
[Ss]erverless
|
||||
[Ss]erverside
|
||||
[Ss]igncryption
|
||||
[Ss]ignins?
|
||||
[Ss]ignouts?
|
||||
@@ -89,6 +94,7 @@ unnested
|
||||
[Uu]pvot(es|ed|ing)
|
||||
Vercel
|
||||
Vite
|
||||
VM(s)?
|
||||
VSCode
|
||||
Vue
|
||||
[Ww]eb[Ss]ockets?
|
||||
|
||||