Supabase Guides # AI & Vectors The best vector database is the database you already have. Supabase provides an open source toolkit for developing AI applications using Postgres and pgvector. Use the Supabase client libraries to store, index, and query your vector embeddings at scale. The toolkit includes: * A [vector store](/docs/guides/ai/vector-columns) and embeddings support using Postgres and pgvector. * A [Python client](/docs/guides/ai/vecs-python-client) for managing unstructured embeddings. * An [embedding generation](/docs/guides/ai/quickstarts/generate-text-embeddings) process using open source models directly in Edge Functions. * [Database migrations](/docs/guides/ai/examples/headless-vector-search#prepare-your-database) for managing structured embeddings. * Integrations with all popular AI providers, such as [OpenAI](/docs/guides/ai/examples/openai), [Hugging Face](/docs/guides/ai/hugging-face), [LangChain](/docs/guides/ai/langchain), and more. ## Search You can use Supabase to build different types of search features for your app, including: * [Semantic search](/docs/guides/ai/semantic-search): search by meaning rather than exact keywords * [Keyword search](/docs/guides/ai/keyword-search): search by words or phrases * [Hybrid search](/docs/guides/ai/hybrid-search): combine semantic search with keyword search ## Examples Check out all of the AI [templates and examples](https://github.com/supabase/supabase/tree/master/examples/ai) in our GitHub repository. ## Integrations ## Case studies # Automatic embeddings Vector embeddings enable powerful [semantic search](/docs/guides/ai/semantic-search) capabilities in Postgres, but managing them alongside your content has traditionally been complex. This guide demonstrates how to automate embedding generation and updates using Supabase [Edge Functions](/docs/guides/functions), [pgmq](/docs/guides/database/extensions/pgmq), [pg\_net](/docs/guides/database/extensions/pg_net), and [pg\_cron](/docs/guides/cron). ## Understanding the challenge When implementing semantic search with pgvector, developers typically need to: 1. Generate embeddings via an external API (like OpenAI) 2. Store these embeddings alongside the content 3. Keep embeddings in sync when content changes 4. Handle failures and retries in the embedding generation process While Postgres [full-text search](/docs/guides/database/full-text-search) can handle this internally through synchronous calls to `to_tsvector` and [triggers](https://www.postgresql.org/docs/current/textsearch-features.html#TEXTSEARCH-UPDATE-TRIGGERS), semantic search requires asynchronous API calls to a provider like OpenAI to generate vector embeddings. This guide demonstrates how to use triggers, queues, and Supabase Edge Functions to bridge this gap. ## Understanding the architecture We'll leverage the following Postgres and Supabase features to create the automated embedding system: 1. [pgvector](/docs/guides/database/extensions/pgvector): Stores and queries vector embeddings 2. [pgmq](/docs/guides/queues): Queues embedding generation requests for processing and retries 3. [pg\_net](/docs/guides/database/extensions/pg_net): Handles asynchronous HTTP requests to Edge Functions directly from Postgres 4. [pg\_cron](/docs/guides/cron): Automatically processes and retries embedding generations 5. [Triggers](/docs/guides/database/postgres/triggers): Detects content changes and enqueues embedding generation requests 6. [Edge Functions](/docs/guides/functions): Generates embeddings via an API like OpenAI (customizable) We'll design the system to: 1. Be generic, so that it can be used with any table and content. This allows you to configure embeddings in multiple places, each with the ability to customize the input used for embedding generation. These will all use the same queue infrastructure and Edge Function to generate the embeddings. 2. Handle failures gracefully, by retrying failed jobs and providing detailed information about the status of each job. ## Implementation We'll start by setting up the infrastructure needed to queue and process embedding generation requests. Then we'll create an example table with triggers to enqueue these embedding requests whenever content is inserted or updated. ### Step 1: Enable extensions First, let's enable the required extensions: ### Step 2: Create utility functions Before we set up our embedding logic, we need to create some utility functions: ```sql -- Schema for utility functions create schema util; -- Utility function to get the Supabase project URL (required for Edge Functions) create function util.project_url() returns text language plpgsql security definer as $$ declare secret_value text; begin -- Retrieve the project URL from Vault select decrypted_secret into secret_value from vault.decrypted_secrets where name = 'project_url'; return secret_value; end; $$; -- Generic function to invoke any Edge Function create or replace function util.invoke_edge_function( name text, body jsonb, timeout_milliseconds int = 5 * 60 * 1000 -- default 5 minute timeout ) returns void language plpgsql as $$ declare headers_raw text; auth_header text; begin -- If we're in a PostgREST session, reuse the request headers for authorization headers_raw := current_setting('request.headers', true); -- Only try to parse if headers are present auth_header := case when headers_raw is not null then (headers_raw::json->>'authorization') else null end; -- Perform async HTTP request to the edge function perform net.http_post( url => util.project_url() || '/functions/v1/' || name, headers => jsonb_build_object( 'Content-Type', 'application/json', 'Authorization', auth_header ), body => body, timeout_milliseconds => timeout_milliseconds ); end; $$; -- Generic trigger function to clear a column on update create or replace function util.clear_column() returns trigger language plpgsql as $$ declare clear_column text := TG_ARGV[0]; begin NEW := NEW #= hstore(clear_column, NULL); return NEW; end; $$; ``` Here we create: * A schema `util` to store utility functions. * A function to retrieve the Supabase project URL from [Vault](/docs/guides/database/vault). We'll add this secret next. * A generic function to invoke any Edge Function with a given name and request body. * A generic trigger function to clear a column on update. This function accepts the column name as an argument and sets it to `NULL` in the `NEW` record. We'll explain how to use this function later. Every project has a unique API URL that is required to invoke Edge Functions. Let's go ahead and add the project URL secret to Vault depending on your environment. When working with a local Supabase stack, add the following to your `supabase/seed.sql` file: ```sql select vault.create_secret('http://api.supabase.internal:8000', 'project_url'); ``` When deploying to the cloud platform, open the [SQL editor](/dashboard/project/_/sql/new) and run the following, replacing `` with your [project's API URL](/dashboard/project/_/settings/api): ```sql select vault.create_secret('', 'project_url'); ``` ### Step 3: Create queue and triggers Our goal is to automatically generate embeddings whenever content is inserted or updated within a table. We can use triggers and queues to achieve this. Our approach is to automatically queue embedding jobs whenever records are inserted or updated in a table, then process them asynchronously using a cron job. If a job fails, it will remain in the queue and be retried in the next scheduled task. First we create a `pgmq` queue for processing embedding requests: ```sql -- Queue for processing embedding jobs select pgmq.create('embedding_jobs'); ``` Next we create a trigger function to queue embedding jobs. We'll use this function to handle both insert and update events: ```sql -- Generic trigger function to queue embedding jobs create or replace function util.queue_embeddings() returns trigger language plpgsql as $$ declare content_function text = TG_ARGV[0]; embedding_column text = TG_ARGV[1]; begin perform pgmq.send( queue_name => 'embedding_jobs', msg => jsonb_build_object( 'id', NEW.id, 'schema', TG_TABLE_SCHEMA, 'table', TG_TABLE_NAME, 'contentFunction', content_function, 'embeddingColumn', embedding_column ) ); return NEW; end; $$; ``` Our `util.queue_embeddings` trigger function is generic and can be used with any table and content function. It accepts two arguments: 1. `content_function`: The name of a function that returns the text content to be embedded. The function should accept a single row as input and return text (see the `embedding_input` example). This allows you to customize the text input passed to the embedding model - for example, you could concatenate multiple columns together like `title` and `content` and use the result as input. 2. `embedding_column`: The name of the destination column where the embedding will be stored. Note that the `util.queue_embeddings` trigger function requires a `for each row` clause to work correctly. See [Usage](#usage) for an example of how to use this trigger function with your table. Next we'll create a function to process the embedding jobs. This function will read jobs from the queue, group them into batches, and invoke the Edge Function to generate embeddings. We'll use `pg_cron` to schedule this function to run every 10 seconds. ```sql -- Function to process embedding jobs from the queue create or replace function util.process_embeddings( batch_size int = 10, max_requests int = 10, timeout_milliseconds int = 5 * 60 * 1000 -- default 5 minute timeout ) returns void language plpgsql as $$ declare job_batches jsonb[]; batch jsonb; begin with -- First get jobs and assign batch numbers numbered_jobs as ( select message || jsonb_build_object('jobId', msg_id) as job_info, (row_number() over (order by 1) - 1) / batch_size as batch_num from pgmq.read( queue_name => 'embedding_jobs', vt => timeout_milliseconds / 1000, qty => max_requests * batch_size ) ), -- Then group jobs into batches batched_jobs as ( select jsonb_agg(job_info) as batch_array, batch_num from numbered_jobs group by batch_num ) -- Finally aggregate all batches into array select array_agg(batch_array) from batched_jobs into job_batches; -- Invoke the embed edge function for each batch foreach batch in array job_batches loop perform util.invoke_edge_function( name => 'embed', body => batch, timeout_milliseconds => timeout_milliseconds ); end loop; end; $$; -- Schedule the embedding processing select cron.schedule( 'process-embeddings', '10 seconds', $$ select util.process_embeddings(); $$ ); ``` Let's discuss some common questions about this approach: #### Why not generate all embeddings in a single Edge Function request? While this is possible, it can lead to long processing times and potential timeouts. Batching allows us to process multiple embeddings concurrently and handle failures more effectively. #### Why not one request per row? This approach can lead to API rate limiting and performance issues. Batching provides a balance between efficiency and reliability. #### Why queue requests instead of processing them immediately? Queuing allows us to handle failures gracefully, retry requests, and manage concurrency more effectively. Specifically we are using `pgmq`'s visibility timeouts to ensure that failed requests are retried. #### How do visibility timeouts work? Every time we read a message from the queue, we set a visibility timeout which tells `pgmq` to hide the message from other readers for a certain period. If the Edge Function fails to process the message within this period, the message becomes visible again and will be retried by the next scheduled task. #### How do we handle retries? We use `pg_cron` to schedule a task that reads messages from the queue and processes them. If the Edge Function fails to process a message, it becomes visible again after a timeout and can be retried by the next scheduled task. #### Is 10 seconds a good interval for processing? This interval is a good starting point, but you may need to adjust it based on your workload and the time it takes to generate embeddings. You can adjust the `batch_size`, `max_requests`, and `timeout_milliseconds` parameters to optimize performance. ### Step 4: Create the Edge Function Finally we'll create the Edge Function to generate embeddings. We'll use OpenAI's API in this example, but you can replace it with any other embedding generation service. Use the Supabase CLI to create a new Edge Function: ```bash supabase functions new embed ``` This will create a new directory `supabase/functions/embed` with an `index.ts` file. Replace the contents of this file with the following: *supabase/functions/embed/index.ts*: ```typescript // Setup type definitions for built-in Supabase Runtime APIs import 'jsr:@supabase/functions-js/edge-runtime.d.ts' // We'll use the OpenAI API to generate embeddings import OpenAI from 'jsr:@openai/openai' import { z } from 'npm:zod' // We'll make a direct Postgres connection to update the document import postgres from 'https://deno.land/x/postgresjs@v3.4.5/mod.js' // Initialize OpenAI client const openai = new OpenAI({ // We'll need to manually set the `OPENAI_API_KEY` environment variable apiKey: Deno.env.get('OPENAI_API_KEY'), }) // Initialize Postgres client const sql = postgres( // `SUPABASE_DB_URL` is a built-in environment variable Deno.env.get('SUPABASE_DB_URL')! ) const jobSchema = z.object({ jobId: z.number(), id: z.number(), schema: z.string(), table: z.string(), contentFunction: z.string(), embeddingColumn: z.string(), }) const failedJobSchema = jobSchema.extend({ error: z.string(), }) type Job = z.infer type FailedJob = z.infer type Row = { id: string content: unknown } const QUEUE_NAME = 'embedding_jobs' // Listen for HTTP requests Deno.serve(async (req) => { if (req.method !== 'POST') { return new Response('expected POST request', { status: 405 }) } if (req.headers.get('content-type') !== 'application/json') { return new Response('expected json body', { status: 400 }) } // Use Zod to parse and validate the request body const parseResult = z.array(jobSchema).safeParse(await req.json()) if (parseResult.error) { return new Response(`invalid request body: ${parseResult.error.message}`, { status: 400, }) } const pendingJobs = parseResult.data // Track jobs that completed successfully const completedJobs: Job[] = [] // Track jobs that failed due to an error const failedJobs: FailedJob[] = [] async function processJobs() { let currentJob: Job | undefined while ((currentJob = pendingJobs.shift()) !== undefined) { try { await processJob(currentJob) completedJobs.push(currentJob) } catch (error) { failedJobs.push({ ...currentJob, error: error instanceof Error ? error.message : JSON.stringify(error), }) } } } try { // Process jobs while listening for worker termination await Promise.race([processJobs(), catchUnload()]) } catch (error) { // If the worker is terminating (e.g. wall clock limit reached), // add pending jobs to fail list with termination reason failedJobs.push( ...pendingJobs.map((job) => ({ ...job, error: error instanceof Error ? error.message : JSON.stringify(error), })) ) } // Log completed and failed jobs for traceability console.log('finished processing jobs:', { completedJobs: completedJobs.length, failedJobs: failedJobs.length, }) return new Response( JSON.stringify({ completedJobs, failedJobs, }), { // 200 OK response status: 200, // Custom headers to report job status headers: { 'content-type': 'application/json', 'x-completed-jobs': completedJobs.length.toString(), 'x-failed-jobs': failedJobs.length.toString(), }, } ) }) /** * Generates an embedding for the given text. */ async function generateEmbedding(text: string) { const response = await openai.embeddings.create({ model: 'text-embedding-3-small', input: text, }) const [data] = response.data if (!data) { throw new Error('failed to generate embedding') } return data.embedding } /** * Processes an embedding job. */ async function processJob(job: Job) { const { jobId, id, schema, table, contentFunction, embeddingColumn } = job // Fetch content for the schema/table/row combination const [row]: [Row] = await sql` select id, ${sql(contentFunction)}(t) as content from ${sql(schema)}.${sql(table)} t where id = ${id} ` if (!row) { throw new Error(`row not found: ${schema}.${table}/${id}`) } if (typeof row.content !== 'string') { throw new Error(`invalid content - expected string: ${schema}.${table}/${id}`) } const embedding = await generateEmbedding(row.content) await sql` update ${sql(schema)}.${sql(table)} set ${sql(embeddingColumn)} = ${JSON.stringify(embedding)} where id = ${id} ` await sql` select pgmq.delete(${QUEUE_NAME}, ${jobId}::bigint) ` } /** * Returns a promise that rejects if the worker is terminating. */ function catchUnload() { return new Promise((reject) => { addEventListener('beforeunload', (ev: any) => { reject(new Error(ev.detail?.reason)) }) }) } ``` The Edge Function listens for incoming HTTP requests from `pg_net` and processes each embedding job. It is a generic worker that can handle embedding jobs for any table and column. It uses OpenAI's API to generate embeddings and updates the corresponding row in the database. It also deletes the job from the queue once it has been processed. The function is designed to process multiple jobs independently. If one job fails, it will not affect the processing of other jobs. The function returns a `200 OK` response with a list of completed and failed jobs. We can use this information to diagnose failed jobs. See [Troubleshooting](#troubleshooting) for more details. You will need to set the `OPENAI_API_KEY` environment variable to authenticate with OpenAI. When running the Edge Function locally, you can add it to a `.env` file: *.env*: OPENAI_API_KEY=your-api-key When you're ready to deploy the Edge Function, set can set the environment variable using the Supabase CLI: ```shell supabase secrets set --env-file .env ``` or ```shell supabase secrets set OPENAI_API_KEY= ``` Alternatively, you can replace the `generateEmbedding` function with your own embedding generation logic. See [Deploy to Production](/docs/guides/functions/deploy) for more information on how to deploy the Edge Function. ## Usage Now that the infrastructure is in place, let's go through an example of how to use this system to automatically generate embeddings for a table of documents. You can use this approach with multiple tables and customize the input for each embedding generation as needed. ### 1. Create table to store documents with embeddings We'll set up a new `documents` table that will store our content and embeddings: ```sql -- Table to store documents with embeddings create table documents ( id integer primary key generated always as identity, title text not null, content text not null, embedding halfvec(1536), created_at timestamp with time zone default now() ); -- Index for vector search over document embeddings create index on documents using hnsw (embedding halfvec_cosine_ops); ``` Our `documents` table stores the title and content of each document along with its vector embedding. We use a `halfvec(1536)` column to store the embeddings. `halfvec` is a `pgvector` data type that stores float values in half precision (16 bits) to save space. Our Edge Function used OpenAI's `text-embedding-3-small` model which generates 1536-dimensional embeddings, so we use the same dimensionality here. Adjust this based on the number of dimensions your embedding model generates. We use an [HNSW index](/docs/guides/ai/vector-indexes/hnsw-indexes) on the vector column. Note that we are choosing `halfvec_cosine_ops` as the index method, which means our future queries will need to use cosine distance (`<=>`) to find similar embeddings. Also note that HNSW indexes support a maximum of 4000 dimensions for `halfvec` vectors, so keep this in mind when choosing an embedding model. If your model generates embeddings with more than 4000 dimensions, you will need to reduce the dimensionality before indexing them. See [Matryoshka embeddings](/blog/matryoshka-embeddings) for a potential solution to shortening dimensions. Also note that the table must have a primary key column named `id` for our triggers to work correctly with the `util.queue_embeddings` function and for our Edge Function to update the correct row. ### 2. Create triggers to enqueue embedding jobs Now we'll set up the triggers to enqueue embedding jobs whenever content is inserted or updated: ```sql -- Customize the input for embedding generation -- e.g. Concatenate title and content with a markdown header create or replace function embedding_input(doc documents) returns text language plpgsql immutable as $$ begin return '# ' || doc.title || E'\n\n' || doc.content; end; $$; -- Trigger for insert events create trigger embed_documents_on_insert after insert on documents for each row execute function util.queue_embeddings('embedding_input', 'embedding'); -- Trigger for update events create trigger embed_documents_on_update after update of title, content -- must match the columns in embedding_input() on documents for each row execute function util.queue_embeddings('embedding_input', 'embedding'); ``` We create 2 triggers: 1. `embed_documents_on_insert`: Enqueues embedding jobs whenever new rows are inserted into the `documents` table. 2. `embed_documents_on_update`: Enqueues embedding jobs whenever the `title` or `content` columns are updated in the `documents` table. Both of these triggers use the same `util.queue_embeddings` function that will queue the embedding jobs for processing. They accept 2 arguments: 1. `embedding_input`: The name of the function that generates the input for embedding generation. This function allows you to customize the text input passed to the embedding model (e.g. concatenating the title and content). The function should accept a single row as input and return text. 2. `embedding`: The name of the destination column where the embedding will be stored. Note that the update trigger only fires when the `title` or `content` columns are updated. This is to avoid unnecessary updates to the embedding column when other columns are updated. Make sure that these columns match the columns used in the `embedding_input` function. #### (Optional) Clearing embeddings on update Note that our trigger will enqueue new embedding jobs when content is updated, but it will not clear any existing embeddings. This means that an embedding can be temporarily out of sync with the content until the new embedding is generated and updated. If it is more important to have *accurate* embeddings than *any* embedding, you can add another trigger to clear the existing embedding until the new one is generated: ```sql -- Trigger to clear the embedding column on update create trigger clear_document_embedding_on_update before update of title, content -- must match the columns in embedding_input() on documents for each row execute function util.clear_column('embedding'); ``` `util.clear_column` is a generic trigger function we created earlier that can be used to clear any column in a table. * It accepts the column name as an argument. This column must be nullable. * It requires a `before` trigger with a `for each row` clause. * It requires the `hstore` extension we created earlier. This example will clear the `embedding` column whenever the `title` or `content` columns are updated (note the `of title, content` clause). This ensures that the embedding is always in sync with the title and content, but it will result in temporary gaps in search results until the new embedding is generated. We intentionally use a `before` trigger because it allows us to modify the record before it's written to disk, avoiding an extra `update` statement that would be needed with an `after` trigger. ### 3. Insert and update documents Let's insert a new document and update its content to see the embedding generation in action: ```sql -- Insert a new document insert into documents (title, content) values ('Understanding Vector Databases', 'Vector databases are specialized...'); -- Immediately check the embedding column select id, embedding from documents where title = 'Understanding Vector Databases'; ``` You should observe that the `embedding` column is initially `null` after inserting the document. This is because the embedding generation is asynchronous and will be processed by the Edge Function in the next scheduled task. Wait up to 10 seconds for the next task to run, then check the `embedding` column again: ```sql select id, embedding from documents where title = 'Understanding Vector Databases'; ``` You should see the generated embedding for the document. Next let's update the content of the document: ```sql -- Update the content of the document update documents set content = 'Vector databases allow you to query...' where title = 'Understanding Vector Databases'; -- Immediately check the embedding column select id, embedding from documents where title = 'Understanding Vector Databases'; ``` You should observe that the `embedding` column is reset to `null` after updating the content. This is because of the trigger we added to clear existing embeddings whenever the content is updated. The embedding will be regenerated by the Edge Function in the next scheduled task. Wait up to 10 seconds for the next task to run, then check the `embedding` column again: ```sql select id, embedding from documents where title = 'Understanding Vector Databases'; ``` You should see the updated embedding for the document. Finally we'll update the title of the document: ```sql -- Update the title of the document update documents set title = 'Understanding Vector Databases with Supabase' where title = 'Understanding Vector Databases'; ``` You should observe that the `embedding` column is once again reset to `null` after updating the title. This is because the trigger we added to clear existing embeddings fires when either the `content` or `title` columns are updated. The embedding will be regenerated by the Edge Function in the next scheduled task. Wait up to 10 seconds for the next task to run, then check the `embedding` column again: ```sql select id, embedding from documents where title = 'Understanding Vector Databases with Supabase'; ``` You should see the updated embedding for the document. ## Troubleshooting The `embed` Edge Function processes a batch of embedding jobs and returns a `200 OK` response with a list of completed and failed jobs in the body. For example: ```json { "completedJobs": [ { "jobId": "1", "id": "1", "schema": "public", "table": "documents", "contentFunction": "embedding_input", "embeddingColumn": "embedding" } ], "failedJobs": [ { "jobId": "2", "id": "2", "schema": "public", "table": "documents", "contentFunction": "embedding_input", "embeddingColumn": "embedding", "error": "error connecting to openai api" } ] } ``` It also returns the number of completed and failed jobs in the response headers. For example: x-completed-jobs: 1 x-failed-jobs: 1 You can also use the `x-deno-execution-id` header to trace the execution of the Edge Function within the [dashboard](/dashboard/project/_/functions) logs. Each failed job includes an `error` field with a description of the failure. Reasons for a job failing could include: * An error generating the embedding via external API * An error connecting to the database * The edge function being terminated (e.g. due to a wall clock limit) * Any other error thrown during processing `pg_net` stores HTTP responses in the `net._http_response` table, which can be queried to diagnose issues with the embedding generation process. ```sql select * from net._http_response where (headers->>'x-failed-jobs')::int > 0; ``` ## Conclusion Automating embedding generation and updates in Postgres allow you to build powerful semantic search capabilities without the complexity of managing embeddings manually. By combining Postgres features like triggers, queues, and other extensions with Supabase Edge Functions, we can create a robust system that handles embedding generation asynchronously and retries failed jobs automatically. This system can be customized to work with any content and embedding generation service, providing a flexible and scalable solution for semantic search in Postgres. ## See also * [What are embeddings?](/docs/guides/ai/concepts) * [Semantic search](/docs/guides/ai/semantic-search) * [Vector indexes](/docs/guides/ai/vector-indexes) * [Supabase Edge Functions](/docs/guides/functions) # Choosing your Compute Add-on Choosing the right Compute Add-on for your vector workload. You have two options for scaling your vector workload: 1. Increase the size of your database. This guide will help you choose the right size for your workload. 2. Spread your workload across multiple databases. You can find more details about this approach in [Engineering for Scale](engineering-for-scale). ## Dimensionality The number of dimensions in your embeddings is the most important factor in choosing the right Compute Add-on. In general, the lower the dimensionality the better the performance. We've provided guidance for some of the more common embedding dimensions below. For each benchmark, we used [Vecs](https://github.com/supabase/vecs) to create a collection, upload the embeddings to a single table, and create both the `IVFFlat` and `HNSW` indexes for `inner-product` distance measure for the embedding column. We then ran a series of queries to measure the performance of different compute add-ons: ## HNSW ### 384 dimensions \[#hnsw-384-dimensions] This benchmark uses the dbpedia-entities-openai-1M dataset containing 1,000,000 embeddings of text, regenerated for 384 dimension embeddings. Each embedding is generated using [gte-small](https://huggingface.co/Supabase/gte-small). ### 960 dimensions \[#hnsw-960-dimensions] This benchmark uses the [gist-960](http://corpus-texmex.irisa.fr/) dataset, which contains 1,000,000 embeddings of images. Each embedding is 960 dimensions. ### 1536 dimensions \[#hnsw-1536-dimensions] This benchmark uses the [dbpedia-entities-openai-1M](https://huggingface.co/datasets/KShivendu/dbpedia-entities-openai-1M) dataset, which contains 1,000,000 embeddings of text. And 224,482 embeddings from [Wikipedia articles](https://huggingface.co/datasets/Supabase/wikipedia-en-embeddings) for compute add-ons `large` and below. Each embedding is 1536 dimensions created with the [OpenAI Embeddings API](https://platform.openai.com/docs/guides/embeddings). ## IVFFlat ### 384 dimensions \[#ivfflat-384-dimensions] This benchmark uses the dbpedia-entities-openai-1M dataset containing 1,000,000 embeddings of text, regenerated for 384 dimension embeddings. Each embedding is generated using [gte-small](https://huggingface.co/Supabase/gte-small). ### 960 dimensions \[#ivfflat-960-dimensions] This benchmark uses the [gist-960](http://corpus-texmex.irisa.fr/) dataset, which contains 1,000,000 embeddings of images. Each embedding is 960 dimensions. ### 1536 dimensions \[#ivfflat-1536-dimensions] This benchmark uses the [dbpedia-entities-openai-1M](https://huggingface.co/datasets/KShivendu/dbpedia-entities-openai-1M) dataset, which contains 1,000,000 embeddings of text. Each embedding is 1536 dimensions created with the [OpenAI Embeddings API](https://platform.openai.com/docs/guides/embeddings). ## Performance tips There are various ways to improve your pgvector performance. Here are some tips: ### Pre-warming your database It's useful to execute a few thousand “warm-up” queries before going into production. This helps help with RAM utilization. This can also help to determine that you've selected the right compute size for your workload. ### Fine-tune index parameters You can increase the Requests per Second by increasing `m` and `ef_construction` or `lists`. This also has an important caveat: building the index takes longer with higher values for these parameters. Check out more tips and the complete step-by-step guide in [Going to Production for AI applications](going-to-prod). ## Benchmark methodology We follow techniques outlined in the [ANN Benchmarks](https://github.com/erikbern/ann-benchmarks) methodology. A Python test runner is responsible for uploading the data, creating the index, and running the queries. The pgvector engine is implemented using [vecs](https://github.com/supabase/vecs), a Python client for pgvector. Each test is run for a minimum of 30-40 minutes. They include a series of experiments executed at different concurrency levels to measure the engine's performance under different load types. The results are then averaged. As a general recommendation, we suggest using a concurrency level of 5 or more for most workloads and 30 or more for high-load workloads. # Concepts Embeddings are core to many AI and vector applications. This guide covers these concepts. If you prefer to get started right away, see our guide on [Generating Embeddings](/docs/guides/ai/quickstarts/generate-text-embeddings). ## What are embeddings? Embeddings capture the "relatedness" of text, images, video, or other types of information. This relatedness is most commonly used for: * **Search:** how similar is a search term to a body of text? * **Recommendations:** how similar are two products? * **Classifications:** how do we categorize a body of text? * **Clustering:** how do we identify trends? Let's explore an example of text embeddings. Say we have three phrases: 1. "The cat chases the mouse" 2. "The kitten hunts rodents" 3. "I like ham sandwiches" Your job is to group phrases with similar meaning. If you are a human, this should be obvious. Phrases 1 and 2 are almost identical, while phrase 3 has a completely different meaning. Although phrases 1 and 2 are similar, they share no common vocabulary (besides "the"). Yet their meanings are nearly identical. How can we teach a computer that these are the same? ## Human language Humans use words and symbols to communicate language. But words in isolation are mostly meaningless - we need to draw from shared knowledge & experience in order to make sense of them. The phrase “You should Google it” only makes sense if you know that Google is a search engine and that people have been using it as a verb. In the same way, we need to train a neural network model to understand human language. An effective model should be trained on millions of different examples to understand what each word, phrase, sentence, or paragraph could mean in different contexts. So how does this relate to embeddings? ## How do embeddings work? Embeddings compress discrete information (words & symbols) into distributed continuous-valued data (vectors). If we took our phrases from before and plot them on a chart, it might look something like this: Phrases 1 and 2 would be plotted close to each other, since their meanings are similar. We would expect phrase 3 to live somewhere far away since it isn't related. If we had a fourth phrase, “Sally ate Swiss cheese”, this might exist somewhere between phrase 3 (cheese can go on sandwiches) and phrase 1 (mice like Swiss cheese). In this example we only have 2 dimensions: the X and Y axis. In reality, we would need many more dimensions to effectively capture the complexities of human language. ## Using embeddings Compared to our 2-dimensional example above, most embedding models will output many more dimensions. For example the open source [`gte-small`](https://huggingface.co/Supabase/gte-small) model outputs 384 dimensions. Why is this useful? Once we have generated embeddings on multiple texts, it is trivial to calculate how similar they are using vector math operations like cosine distance. A common use case for this is search. Your process might look something like this: 1. Pre-process your knowledge base and generate embeddings for each page 2. Store your embeddings to be referenced later 3. Build a search page that prompts your user for input 4. Take user's input, generate a one-time embedding, then perform a similarity search against your pre-processed embeddings. 5. Return the most similar pages to the user ## See also * [Structured and Unstructured embeddings](/docs/guides/ai/structured-unstructured) # Engineering for Scale Building an enterprise-grade vector architecture. Content sources for vectors can be extremely large. As you grow you should run your Vector workloads across several secondary databases (sometimes called "pods"), which allows each collection to scale independently. ## Simple workloads For small workloads, it's typical to store your data in a single database. If you've used [Vecs](/docs/guides/ai/vecs-python-client) to create 3 different collections, you can expose collections to your web or mobile application using [views](/docs/guides/database/tables#views): For example, with 3 collections, called `docs`, `posts`, and `images`, we could expose the "docs" inside the public schema like this: ```sql create view public.docs as select id, embedding, metadata, # Expose the metadata as JSON (metadata->>'url')::text as url # Extract the URL as a string from vector ``` You can then use any of the client libraries to access your collections within your applications: ```js const { data, error } = await supabase .from('docs') .select('id, embedding, metadata') .eq('url', '/hello-world') ``` ## Enterprise workloads As you move into production, we recommend splitting your collections into separate projects. This is because it allows your vector stores to scale independently of your production data. Vectors typically grow faster than operational data, and they have different resource requirements. Running them on separate databases removes the single-point-of-failure. You can use as many secondary databases as you need to manage your collections. With this architecture, you have 2 options for accessing collections within your application: 1. Query the collections directly using Vecs. 2. Access the collections from your Primary database through a Wrapper. You can use both of these in tandem to suit your use-case. We recommend option `1` wherever possible, as it offers the most scalability. ### Query collections using Vecs Vecs provides methods for querying collections, either using a [cosine similarity function](https://supabase.github.io/vecs/api/#basic) or with [metadata filtering](https://supabase.github.io/vecs/api/#metadata-filtering). ```python # cosine similarity docs.query(query_vector=[0.4,0.5,0.6], limit=5) # metadata filtering docs.query( query_vector=[0.4,0.5,0.6], limit=5, filters={"year": {"$eq": 2012}}, # metadata filters ) ``` ### Accessing external collections using Wrappers Supabase supports [Foreign Data Wrappers](/blog/postgres-foreign-data-wrappers-rust). Wrappers allow you to connect two databases together so that you can query them over the network. This involves 2 steps: connecting to your remote database from the primary and creating a Foreign Table. #### Connecting your remote database Inside your Primary database we need to provide the credentials to access the secondary database: ```sql create extension postgres_fdw; create server docs_server foreign data wrapper postgres_fdw options (host 'db.xxx.supabase.co', port '5432', dbname 'postgres'); create user mapping for docs_user server docs_server options (user 'postgres', password 'password'); ``` #### Create a foreign table We can now create a foreign table to access the data in our secondary project. ```sql create foreign table docs ( id text not null, embedding vector(384), metadata jsonb, url text ) server docs_server options (schema_name 'public', table_name 'docs'); ``` This looks very similar to our View example above, and you can continue to use the client libraries to access your collections through the foreign table: ```js const { data, error } = await supabase .from('docs') .select('id, embedding, metadata') .eq('url', '/hello-world') ``` ### Enterprise architecture This diagram provides an example architecture that allows you to access the collections either with our client libraries or using Vecs. You can add as many secondary databases as you need (in this example we only show one): # Building ChatGPT plugins Use Supabase as a Retrieval Store for your ChatGPT plugin. ChatGPT recently released [Plugins](https://openai.com/blog/chatgpt-plugins) which help ChatGPT access up-to-date information, run computations, or use third-party services. If you're building a plugin for ChatGPT, you'll probably want to answer questions from a specific source. We can solve this with “retrieval plugins”, which allow ChatGPT to access information from a database. ## What is ChatGPT Retrieval Plugin? A [Retrieval Plugin](https://github.com/openai/chatgpt-retrieval-plugin) is a Python project designed to inject external data into a ChatGPT conversation. It does a few things: 1. Turn documents into smaller chunks. 2. Converts chunks into embeddings using OpenAI's `text-embedding-ada-002` model. 3. Stores the embeddings into a vector database. 4. Queries the vector database for relevant documents when a question is asked. It allows ChatGPT to dynamically pull relevant information into conversations from your data sources. This could be PDF documents, Confluence, or Notion knowledge bases. ## Example: Chat with Postgres docs Let’s build an example where we can “ask ChatGPT questions” about the Postgres documentation. Although ChatGPT already knows about the Postgres documentation because it is publicly available, this is a simple example which demonstrates how to work with PDF files. This plugin requires several steps: 1. Download all the [Postgres docs as a PDF](https://www.postgresql.org/files/documentation/pdf/15/postgresql-15-US.pdf) 2. Convert the docs into chunks of embedded text and store them in Supabase 3. Run our plugin locally so that we can ask questions about the Postgres docs. We'll be saving the Postgres documentation in Postgres, and ChatGPT will be retrieving the documentation whenever a user asks a question: ### Step 1: Fork the ChatGPT Retrieval Plugin repository Fork the ChatGPT Retrieval Plugin repository to your GitHub account and clone it to your local machine. Read through the `README.md` file to understand the project structure. ### Step 2: Install dependencies Choose your desired datastore provider and remove unused dependencies from `pyproject.toml`. For this example, we'll use Supabase. And install dependencies with Poetry: ```bash poetry install ``` ### Step 3: Create a Supabase project Create a [Supabase project](https://supabase.com/dashboard) and database by following the instructions [here](https://supabase.com/docs/guides/platform). Export the environment variables required for the retrieval plugin to work: ```bash export OPENAI_API_KEY= export DATASTORE=supabase export SUPABASE_URL= export SUPABASE_SERVICE_ROLE_KEY= ``` For Postgres datastore, you'll need to export these environment variables instead: ```bash export OPENAI_API_KEY= export DATASTORE=postgres export PG_HOST= export PG_PASSWORD= ``` ### Step 4: Run Postgres locally To start quicker you may use Supabase CLI to spin everything up locally as it already includes pgvector from the start. Install `supabase-cli`, go to the `examples/providers` folder in the repo and run: ```bash supabase start ``` This will pull all docker images and run Supabase stack in docker on your local machine. It will also apply all the necessary migrations to set the whole thing up. You can then use your local setup the same way, just export the environment variables and follow to the next steps. Using `supabase-cli` is not required and you can use any other docker image or hosted version of Postgres that includes `pgvector`. Just make sure you run migrations from `examples/providers/supabase/migrations/20230414142107_init_pg_vector.sql`. ### Step 5: Obtain OpenAI API key To create embeddings Plugin uses OpenAI API and `text-embedding-ada-002` model. Each time we add some data to our datastore, or try to query relevant information from it, embedding will be created either for inserted data chunk, or for the query itself. To make it work we need to export `OPENAI_API_KEY`. If you already have an account in OpenAI, you just need to go to [User Settings - API keys](https://platform.openai.com/account/api-keys) and Create new secret key. ![OpenAI Secret Keys](/docs/img/ai/chatgpt-plugins/openai-secret-keys.png) ### Step 6: Run the plugin Execute the following command to run the plugin: ```bash poetry run dev # output INFO: Will watch for changes in these directories: ['./chatgpt-retrieval-plugin'] INFO: Uvicorn running on http://localhost:3333 (Press CTRL+C to quit) INFO: Started reloader process [87843] using WatchFiles INFO: Started server process [87849] INFO: Waiting for application startup. INFO: Application startup complete. ``` The plugin will start on your localhost - port `:3333` by default. ### Step 6: Populating data in the datastore For this example, we'll upload Postgres documentation to the datastore. Download the [Postgres documentation](https://www.postgresql.org/files/documentation/pdf/15/postgresql-15-US.pdf) and use the `/upsert-file` endpoint to upload it: ```bash curl -X POST -F \\"file=@./postgresql-15-US.pdf\\" ``` The plugin will split your data and documents into smaller chunks automatically. You can view the chunks using the Supabase dashboard or any other SQL client you prefer. The entire Postgres Documentation yielded 7,904 records, which is not a lot, but we can try to add index for `embedding` column to speed things up by a little. To do so, you should run the following SQL command: ```sql create index on documents using hnsw (embedding vector_ip_ops) with (lists = 10); ``` This will create an index for the inner product distance function. Important to note that it is an approximate index. It will change the logic from performing the exact nearest neighbor search to the approximate nearest neighbor search. We are using `lists = 10`, because as a general guideline, you should start looking for optimal lists constant value with the formula: `rows / 1000` when you have less than 1 million records in your table. ### Step 7: Using our plugin within ChatGPT To integrate our plugin with ChatGPT, register it in the ChatGPT dashboard. Assuming you have access to ChatGPT Plugins and plugin development, select the Plugins model in a new chat, then choose "Plugin store" and "Develop your own plugin." Enter `localhost:3333` into the domain input, and your plugin is now part of ChatGPT. ![ChatGPT Plugin Store](/docs/img/ai/chatgpt-plugins/chatgpt-plugin-store.png) ![ChatGPT Local Plugin](/docs/img/ai/chatgpt-plugins/chatgpt-local-plugin.png) You can now ask questions about Postgres and receive answers derived from the documentation. Let's try it out: ask ChatGPT to find out when to use `check` and when to use `using`. You will be able to see what queries were sent to our plugin and what it responded to. ![Ask ChatGPT](/docs/img/ai/chatgpt-plugins/ask-chatgpt.png) And after ChatGPT receives a response from the plugin it will answer your question with the data from the documentation. ![ChatGPT Reply](/docs/img/ai/chatgpt-plugins/chatgpt-reply.png) ## Resources * ChatGPT Retrieval Plugin: [github.com/openai/chatgpt-retrieval-plugin](https://github.com/openai/chatgpt-retrieval-plugin) * ChatGPT Plugins: [official documentation](https://platform.openai.com/docs/plugins/introduction) # Adding generative Q&A for your documentation Learn how to build a ChatGPT-style doc search powered using our headless search toolkit. Supabase provides a [Headless Search Toolkit](https://github.com/supabase/headless-vector-search) for adding "Generative Q\&A" to your documentation. The toolkit is "headless", so that you can integrate it into your existing website and style it to match your website theme. You can see how this works with the Supabase docs. Just hit `cmd+k` and "ask" for something like "what are the features of Supabase?". You will see that the response is streamed back, using the information provided in the docs: ![headless search](/docs/img/ai/headless-search/headless.png) ## Tech stack * Supabase: Database & Edge Functions. * OpenAI: Embeddings and completions. * GitHub Actions: for ingesting your markdown docs. ## Toolkit This toolkit consists of 2 parts: * The [Headless Vector Search](https://github.com/supabase/headless-vector-search) template which you can deploy in your own organization. * A [GitHub Action](https://github.com/supabase/embeddings-generator) which will ingest your markdown files, convert them to embeddings, and store them in your database. ## Usage There are 3 steps to build similarity search inside your documentation: 1. Prepare your database. 2. Ingest your documentation. 3. Add a search interface. ### Prepare your database To prepare, create a [new Supabase project](https://database.new) and store the database and API credentials, which you can find in the project [settings](https://supabase.com/dashboard/project/_/settings). Now we can use the [Headless Vector Search](https://github.com/supabase/headless-vector-search#set-up) instructions to set up the database: 1. Clone the repo to your local machine: `git clone git@github.com:supabase/headless-vector-search.git` 2. Link the repo to your remote project: `supabase link --project-ref XXX` 3. Apply the database migrations: `supabase db push` 4. Set your OpenAI key as a secret: `supabase secrets set OPENAI_API_KEY=sk-xxx` 5. Deploy the Edge Functions: `supabase functions deploy --no-verify-jwt` 6. Expose `docs` schema via API in Supabase Dashboard [settings](https://supabase.com/dashboard/project/_/settings/api) > `API Settings` > `Exposed schemas` ### Ingest your documentation Now we need to push your documentation into the database as embeddings. You can do this manually, but to make it easier we've created a [GitHub Action](https://github.com/marketplace/actions/supabase-embeddings-generator) which can update your database every time there is a Pull Request. In your knowledge base repository, create a new action called `.github/workflows/generate_embeddings.yml` with the following content: ```yml name: 'generate_embeddings' on: # run on main branch changes push: branches: - main jobs: generate: runs-on: ubuntu-latest steps: - uses: actions/checkout@v3 - uses: supabase/embeddings-generator@v0.0.x # Update this to the latest version. with: supabase-url: 'https://your-project-ref.supabase.co' # Update this to your project URL. supabase-service-role-key: ${{ secrets.SUPABASE_SERVICE_ROLE_KEY }} openai-key: ${{ secrets.OPENAI_API_KEY }} docs-root-path: 'docs' # the path to the root of your md(x) files ``` Make sure to choose the latest version, and set your `SUPABASE_SERVICE_ROLE_KEY` and `OPENAI_API_KEY` as repository secrets in your repo settings (settings > secrets > actions). ### Add a search interface Now inside your docs, you need to create a search interface. Because this is a headless interface, you can use it with any language. The only requirement is that you send the user query to the `query` Edge Function, which will stream an answer back from OpenAI. It might look something like this: ```js const onSubmit = (e: Event) => { e.preventDefault() answer.value = "" isLoading.value = true const query = new URLSearchParams({ query: inputRef.current!.value }) const projectUrl = `https://your-project-ref.supabase.co/functions/v1` const queryURL = `${projectURL}/${query}` const eventSource = new EventSource(queryURL) eventSource.addEventListener("error", (err) => { isLoading.value = false console.error(err) }) eventSource.addEventListener("message", (e: MessageEvent) => { isLoading.value = false if (e.data === "[DONE]") { eventSource.close() return } const completionResponse: CreateCompletionResponse = JSON.parse(e.data) const text = completionResponse.choices[0].text answer.value += text }); isLoading.value = true } ``` ## Resources * Read about how we built [ChatGPT for the Supabase Docs](https://supabase.com/blog/chatgpt-supabase-docs). * Read the pgvector Docs for [Embeddings and vector similarity](/docs/guides/database/extensions/pgvector) * See how to build something like this from scratch [using Next.js](/docs/guides/ai/examples/nextjs-vector-search). # Generate image captions using Hugging Face Use the Hugging Face Inference API to make calls to 100,000+ Machine Learning models from Supabase Edge Functions. We can combine Hugging Face with [Supabase Storage](https://supabase.com/storage) and [Database Webhooks](https://supabase.com/docs/guides/database/webhooks) to automatically caption for any image we upload to a storage bucket. ## About Hugging Face [Hugging Face](https://huggingface.co/) is the collaboration platform for the machine learning community. [Huggingface.js](https://huggingface.co/docs/huggingface.js/index) provides a convenient way to make calls to 100,000+ Machine Learning models, making it easy to incorporate AI functionality into your [Supabase Edge Functions](https://supabase.com/edge-functions). ## Setup * Open your Supabase project dashboard or [create a new project](https://supabase.com/dashboard/projects). * [Create a new bucket](https://supabase.com/dashboard/project/_/storage/buckets) called `images`. * Generate TypeScript types from remote Database. * Create a new Database table called `image_caption`. * Create `id` column of type `uuid` which references `storage.objects.id`. * Create a `caption` column of type `text`. * Regenerate TypeScript types to include new `image_caption` table. * Deploy the function to Supabase: `supabase functions deploy huggingface-image-captioning`. * Create the Database Webhook in the [Supabase Dashboard](https://supabase.com/dashboard/project/_/database/hooks) to trigger the `huggingface-image-captioning` function anytime a record is added to the `storage.objects` table. ## Generate TypeScript types To generate the types.ts file for the storage and public schemas, run the following command in the terminal: ```bash supabase gen types typescript --project-id=your-project-ref --schema=storage,public > supabase/functions/huggingface-image-captioning/types.ts ``` ## Code Find the complete code on [GitHub](https://github.com/supabase/supabase/tree/master/examples/edge-functions/supabase/functions/huggingface-image-captioning). ```ts import { serve } from 'https://deno.land/std@0.168.0/http/server.ts' import { HfInference } from 'https://esm.sh/@huggingface/inference@2.3.2' import { createClient } from 'jsr:@supabase/supabase-js@2' import { Database } from './types.ts' console.log('Hello from `huggingface-image-captioning` function!') const hf = new HfInference(Deno.env.get('HUGGINGFACE_ACCESS_TOKEN')) type SoRecord = Database['storage']['Tables']['objects']['Row'] interface WebhookPayload { type: 'INSERT' | 'UPDATE' | 'DELETE' table: string record: SoRecord schema: 'public' old_record: null | SoRecord } serve(async (req) => { const payload: WebhookPayload = await req.json() const soRecord = payload.record const supabaseAdminClient = createClient( // Supabase API URL - env var exported by default when deployed. Deno.env.get('SUPABASE_URL') ?? '', // Supabase API SERVICE ROLE KEY - env var exported by default when deployed. Deno.env.get('SUPABASE_SERVICE_ROLE_KEY') ?? '' ) // Construct image url from storage const { data, error } = await supabaseAdminClient.storage .from(soRecord.bucket_id!) .createSignedUrl(soRecord.path_tokens!.join('/'), 60) if (error) throw error const { signedUrl } = data // Run image captioning with Huggingface const imgDesc = await hf.imageToText({ data: await (await fetch(signedUrl)).blob(), model: 'nlpconnect/vit-gpt2-image-captioning', }) // Store image caption in Database table await supabaseAdminClient .from('image_caption') .insert({ id: soRecord.id!, caption: imgDesc.generated_text }) .throwOnError() return new Response('ok') }) ``` # Image Search with OpenAI CLIP Implement image search with the OpenAI CLIP Model and Supabase Vector. The [OpenAI CLIP Model](https://github.com/openai/CLIP) was trained on a variety of (image, text)-pairs. You can use the CLIP model for: * Text-to-Image / Image-To-Text / Image-to-Image / Text-to-Text Search * You can fine-tune it on your own image and text data with the regular `SentenceTransformers` training code. [`SentenceTransformers`](https://www.sbert.net/examples/applications/image-search/README.html) provides models that allow you to embed images and text into the same vector space. You can use this to find similar images as well as to implement image search. You can find the full application code as a Python Poetry project on [GitHub](https://github.com/supabase/supabase/tree/master/examples/ai/image_search#image-search-with-supabase-vector). ## Create a new Python project with Poetry [Poetry](https://python-poetry.org/) provides packaging and dependency management for Python. If you haven't already, install poetry via pip: ```shell pip install poetry ``` Then initialize a new project: ```shell poetry new image-search ``` ## Setup Supabase project If you haven't already, [install the Supabase CLI](/docs/guides/cli), then initialize Supabase in the root of your newly created poetry project: ```shell supabase init ``` Next, start your local Supabase stack: ```shell supabase start ``` This will start up the Supabase stack locally and print out a bunch of environment details, including your local `DB URL`. Make a note of that for later user. ## Install the dependencies We will need to add the following dependencies to our project: * [`vecs`](https://github.com/supabase/vecs#vecs): Supabase Vector Python Client. * [`sentence-transformers`](https://huggingface.co/sentence-transformers/clip-ViT-B-32): a framework for sentence, text and image embeddings (used with OpenAI CLIP model) * [`matplotlib`](https://matplotlib.org/): for displaying our image result ```shell poetry add vecs sentence-transformers matplotlib ``` ## Import the necessary dependencies At the top of your main python script, import the dependencies and store your `DB URL` from above in a variable: ```python from PIL import Image from sentence_transformers import SentenceTransformer import vecs from matplotlib import pyplot as plt from matplotlib import image as mpimg DB_CONNECTION = "postgresql://postgres:postgres@localhost:54322/postgres" ``` ## Create embeddings for your images In the root of your project, create a new folder called `images` and add some images. You can use the images from the example project on [GitHub](https://github.com/supabase/supabase/tree/master/examples/ai/image_search/images) or you can find license free images on [Unsplash](https://unsplash.com). Next, create a `seed` method, which will create a new Supabase Vector Collection, generate embeddings for your images, and upsert the embeddings into your database: ```python def seed(): # create vector store client vx = vecs.create_client(DB_CONNECTION) # create a collection of vectors with 3 dimensions images = vx.get_or_create_collection(name="image_vectors", dimension=512) # Load CLIP model model = SentenceTransformer('clip-ViT-B-32') # Encode an image: img_emb1 = model.encode(Image.open('./images/one.jpg')) img_emb2 = model.encode(Image.open('./images/two.jpg')) img_emb3 = model.encode(Image.open('./images/three.jpg')) img_emb4 = model.encode(Image.open('./images/four.jpg')) # add records to the *images* collection images.upsert( records=[ ( "one.jpg", # the vector's identifier img_emb1, # the vector. list or np.array {"type": "jpg"} # associated metadata ), ( "two.jpg", img_emb2, {"type": "jpg"} ), ( "three.jpg", img_emb3, {"type": "jpg"} ), ( "four.jpg", img_emb4, {"type": "jpg"} ) ] ) print("Inserted images") # index the collection for fast search performance images.create_index() print("Created index") ``` Add this method as a script in your `pyproject.toml` file: ```toml [tool.poetry.scripts] seed = "image_search.main:seed" search = "image_search.main:search" ``` After activating the virtual environment with `poetry shell` you can now run your seed script via `poetry run seed`. You can inspect the generated embeddings in your local database by visiting the local Supabase dashboard at [localhost:54323](http://localhost:54323/project/default/editor), selecting the `vecs` schema, and the `image_vectors` database. ## Perform an image search from a text query With Supabase Vector we can query our embeddings. We can use either an image as search input or alternative we can generate an embedding from a string input and use that as the query input: ```python def search(): # create vector store client vx = vecs.create_client(DB_CONNECTION) images = vx.get_or_create_collection(name="image_vectors", dimension=512) # Load CLIP model model = SentenceTransformer('clip-ViT-B-32') # Encode text query query_string = "a bike in front of a red brick wall" text_emb = model.encode(query_string) # query the collection filtering metadata for "type" = "jpg" results = images.query( data=text_emb, # required limit=1, # number of records to return filters={"type": {"$eq": "jpg"}}, # metadata filters ) result = results[0] print(result) plt.title(result) image = mpimg.imread('./images/' + result) plt.imshow(image) plt.show() ``` By limiting the query to one result, we can show the most relevant image to the user. Finally we use `matplotlib` to show the image result to the user. Go ahead and test it out by running `poetry run search` and you will be presented with an image of a "bike in front of a red brick wall". ## Conclusion With just a couple of lines of Python you are able to implement image search as well as reverse image search using OpenAI's CLIP model and Supabase Vector. # Video Search with Mixpeek Multimodal Embeddings Implement video search with the Mixpeek Multimodal Embed API and Supabase Vector. The [Mixpeek Embed API](https://docs.mixpeek.com/api-documentation/inference/embed) allows you to generate embeddings for various types of content, including videos and text. You can use these embeddings for: * Text-to-Video / Video-To-Text / Video-to-Video / Text-to-Text Search * Fine-tuning on your own video and text data This guide demonstrates how to implement video search using Mixpeek Embed for video processing and embedding, and Supabase Vector for storing and querying embeddings. You can find the full application code as a Python Poetry project on [GitHub](https://github.com/yourusername/your-repo-name). ## Create a new Python project with Poetry [Poetry](https://python-poetry.org/) provides packaging and dependency management for Python. If you haven't already, install poetry via pip: ```shell pip install poetry ``` Then initialize a new project: ```shell poetry new video-search ``` ## Setup Supabase project If you haven't already, [install the Supabase CLI](https://supabase.com/docs/guides/cli), then initialize Supabase in the root of your newly created poetry project: ```shell supabase init ``` Next, start your local Supabase stack: ```shell supabase start ``` This will start up the Supabase stack locally and print out a bunch of environment details, including your local `DB URL`. Make a note of that for later use. ## Install the dependencies Add the following dependencies to your project: * [`supabase`](https://github.com/supabase-community/supabase-py): Supabase Python Client * [`mixpeek`](https://github.com/mixpeek/python-client): Mixpeek Python Client for embedding generation ```shell poetry add supabase mixpeek ``` ## Import the necessary dependencies At the top of your main Python script, import the dependencies and store your environment variables: ```python from supabase import create_client, Client from mixpeek import Mixpeek import os SUPABASE_URL = os.getenv("SUPABASE_URL") SUPABASE_KEY = os.getenv("SUPABASE_API_KEY") MIXPEEK_API_KEY = os.getenv("MIXPEEK_API_KEY") ``` ## Create embeddings for your videos Next, create a `seed` method, which will create a new Supabase table, generate embeddings for your video chunks, and insert the embeddings into your database: ```python def seed(): # Initialize Supabase and Mixpeek clients supabase: Client = create_client(SUPABASE_URL, SUPABASE_KEY) mixpeek = Mixpeek(MIXPEEK_API_KEY) # Create a table for storing video chunk embeddings supabase.table("video_chunks").create({ "id": "text", "start_time": "float8", "end_time": "float8", "embedding": "vector(768)", "metadata": "jsonb" }) # Process and embed video video_url = "https://example.com/your_video.mp4" processed_chunks = mixpeek.tools.video.process( video_source=video_url, chunk_interval=1, # 1 second intervals resolution=[720, 1280] ) for chunk in processed_chunks: print(f"Processing video chunk: {chunk['start_time']}") # Generate embedding using Mixpeek embed_response = mixpeek.embed.video( model_id="vuse-generic-v1", input=chunk['base64_chunk'], input_type="base64" ) # Insert into Supabase supabase.table("video_chunks").insert({ "id": f"chunk_{chunk['start_time']}", "start_time": chunk["start_time"], "end_time": chunk["end_time"], "embedding": embed_response['embedding'], "metadata": {"video_url": video_url} }).execute() print("Video processed and embeddings inserted") # Create index for fast search performance supabase.query("CREATE INDEX ON video_chunks USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100)").execute() print("Created index") ``` Add this method as a script in your `pyproject.toml` file: ```toml [tool.poetry.scripts] seed = "video_search.main:seed" search = "video_search.main:search" ``` After activating the virtual environment with `poetry shell`, you can now run your seed script via `poetry run seed`. You can inspect the generated embeddings in your local database by visiting the local Supabase dashboard at [localhost:54323](http://localhost:54323/project/default/editor). ## Perform a video search from a text query With Supabase Vector, you can query your embeddings. You can use either a video clip as search input or alternatively, you can generate an embedding from a string input and use that as the query input: ```python def search(): # Initialize Supabase and Mixpeek clients supabase: Client = create_client(SUPABASE_URL, SUPABASE_KEY) mixpeek = Mixpeek(MIXPEEK_API_KEY) # Generate embedding for text query query_string = "a car chase scene" text_emb = mixpeek.embed.video( model_id="vuse-generic-v1", input=query_string, input_type="text" ) # Query the collection results = supabase.rpc( 'match_video_chunks', { 'query_embedding': text_emb['embedding'], 'match_threshold': 0.8, 'match_count': 5 } ).execute() # Display the results if results.data: for result in results.data: print(f"Matched chunk from {result['start_time']} to {result['end_time']} seconds") print(f"Video URL: {result['metadata']['video_url']}") print(f"Similarity: {result['similarity']}") print("---") else: print("No matching video chunks found") ``` This query will return the top 5 most similar video chunks from your database. You can now test it out by running `poetry run search`, and you will be presented with the most relevant video chunks to the query "a car chase scene". ## Conclusion With just a couple of Python scripts, you are able to implement video search as well as reverse video search using Mixpeek Embed and Supabase Vector. This approach allows for powerful semantic search capabilities that can be integrated into various applications, enabling you to search through video content using both text and video queries. # Vector search with Next.js and OpenAI Learn how to build a ChatGPT-style doc search powered by Next.js, OpenAI, and Supabase. While our [Headless Vector search](/docs/guides/ai/examples/headless-vector-search) provides a toolkit for generative Q\&A, in this tutorial we'll go more in-depth, build a custom ChatGPT-like search experience from the ground-up using Next.js. You will: 1. Convert your markdown into embeddings using OpenAI. 2. Store you embeddings in Postgres using pgvector. 3. Deploy a function for answering your users' questions. You can read our [Supabase Clippy](https://supabase.com/blog/chatgpt-supabase-docs) blog post for a full example. We assume that you have a Next.js project with a collection of `.mdx` files nested inside your `pages` directory. We will start developing locally with the Supabase CLI and then push our local database changes to our hosted Supabase project. You can find the [full Next.js example on GitHub](https://github.com/supabase-community/nextjs-openai-doc-search). ## Create a project 1. [Create a new project](https://supabase.com/dashboard) in the Supabase Dashboard. 2. Enter your project details. 3. Wait for the new database to launch. ## Prepare the database Let's prepare the database schema. We can use the "OpenAI Vector Search" quickstart in the [SQL Editor](https://supabase.com/dashboard/project/_/sql), or you can copy/paste the SQL below and run it yourself. ## Pre-process the knowledge base at build time With our database set up, we need to process and store all `.mdx` files in the `pages` directory. You can find the full script [here](https://github.com/supabase-community/nextjs-openai-doc-search/blob/main/lib/generate-embeddings.ts), or follow the steps below: ## Create text completion with OpenAI API Anytime a user asks a question, we need to create an embedding for their question, perform a similarity search, and then send a text completion request to the OpenAI API with the query and then context content merged together into a prompt. All of this is glued together in a [Vercel Edge Function](https://vercel.com/docs/concepts/functions/edge-functions), the code for which can be found on [GitHub](https://github.com/supabase-community/nextjs-openai-doc-search/blob/main/pages/api/vector-search.ts). ## Display the answer on the frontend In a last step, we need to process the event stream from the OpenAI API and print the answer to the user. The full code for this can be found on [GitHub](https://github.com/supabase-community/nextjs-openai-doc-search/blob/main/components/SearchDialog.tsx). ```ts const handleConfirm = React.useCallback( async (query: string) => { setAnswer(undefined) setQuestion(query) setSearch('') dispatchPromptData({ index: promptIndex, answer: undefined, query }) setHasError(false) setIsLoading(true) const eventSource = new SSE(`api/vector-search`, { headers: { apikey: process.env.NEXT_PUBLIC_SUPABASE_ANON_KEY ?? '', Authorization: `Bearer ${process.env.NEXT_PUBLIC_SUPABASE_ANON_KEY}`, 'Content-Type': 'application/json', }, payload: JSON.stringify({ query }), }) function handleError(err: T) { setIsLoading(false) setHasError(true) console.error(err) } eventSource.addEventListener('error', handleError) eventSource.addEventListener('message', (e: any) => { try { setIsLoading(false) if (e.data === '[DONE]') { setPromptIndex((x) => { return x + 1 }) return } const completionResponse: CreateCompletionResponse = JSON.parse(e.data) const text = completionResponse.choices[0].text setAnswer((answer) => { const currentAnswer = answer ?? '' dispatchPromptData({ index: promptIndex, answer: currentAnswer + text, }) return (answer ?? '') + text }) } catch (err) { handleError(err) } }) eventSource.stream() eventSourceRef.current = eventSource setIsLoading(true) }, [promptIndex, promptData] ) ``` ## Learn more Want to learn more about the awesome tech that is powering this? * Read about how we built [ChatGPT for the Supabase Docs](https://supabase.com/blog/chatgpt-supabase-docs). * Read the pgvector Docs for [Embeddings and vector similarity](https://supabase.com/docs/guides/database/extensions/pgvector) * Watch Greg's video for a full breakdown: # Generating OpenAI GPT3 completions Generate GPT text completions using OpenAI and Supabase Edge Functions. OpenAI provides a [completions API](https://platform.openai.com/docs/api-reference/completions) that allows you to use their generative GPT models in your own applications. OpenAI's API is intended to be used from the server-side. Supabase offers Edge Functions to make it easy to interact with third party APIs like OpenAI. ## Setup Supabase project If you haven't already, [install the Supabase CLI](/docs/guides/cli) and initialize your project: ```shell supabase init ``` ## Create edge function Scaffold a new edge function called `openai` by running: ```shell supabase functions new openai ``` A new edge function will now exist under `./supabase/functions/openai/index.ts`. We'll design the function to take your user's query (via POST request) and forward it to OpenAI's API. ```ts index.ts import OpenAI from 'https://deno.land/x/openai@v4.24.0/mod.ts' Deno.serve(async (req) => { const { query } = await req.json() const apiKey = Deno.env.get('OPENAI_API_KEY') const openai = new OpenAI({ apiKey: apiKey, }) // Documentation here: https://github.com/openai/openai-node const chatCompletion = await openai.chat.completions.create({ messages: [{ role: 'user', content: query }], // Choose model from here: https://platform.openai.com/docs/models model: 'gpt-3.5-turbo', stream: false, }) const reply = chatCompletion.choices[0].message.content return new Response(reply, { headers: { 'Content-Type': 'text/plain' }, }) }) ``` Note that we are setting `stream` to `false` which will wait until the entire response is complete before returning. If you wish to stream GPT's response word-by-word back to your client, set `stream` to `true`. ## Create OpenAI key You may have noticed we were passing `OPENAI_API_KEY` in the Authorization header to OpenAI. To generate this key, go to https://platform.openai.com/account/api-keys and create a new secret key. After getting the key, copy it into a new file called `.env.local` in your `./supabase` folder: OPENAI_API_KEY=your-key-here ## Run locally Serve the edge function locally by running: ```bash supabase functions serve --env-file ./supabase/.env.local --no-verify-jwt ``` Notice how we are passing in the `.env.local` file. Use cURL or Postman to make a POST request to http://localhost:54321/functions/v1/openai. ```bash curl -i --location --request POST http://localhost:54321/functions/v1/openai \ --header 'Content-Type: application/json' \ --data '{"query":"What is Supabase?"}' ``` You should see a GPT response come back from OpenAI! ## Deploy Deploy your function to the cloud by running: ```bash supabase functions deploy --no-verify-jwt openai supabase secrets set --env-file ./supabase/.env.local ``` ## Go deeper If you're interesting in learning how to use this to build your own ChatGPT, read [the blog post](/blog/chatgpt-supabase-docs) and check out the video: # Semantic Image Search with Amazon Titan Implement semantic image search with Amazon Titan and Supabase Vector in Python. [Amazon Bedrock](https://aws.amazon.com/bedrock) is a fully managed service that offers a choice of high-performing foundation models (FMs) from leading AI companies like AI21 Labs, Anthropic, Cohere, Meta, Mistral AI, Stability AI, and Amazon. Each model is accessible through a common API which implements a broad set of features to help build generative AI applications with security, privacy, and responsible AI in mind. [Amazon Titan](https://aws.amazon.com/bedrock/titan/) is a family of foundation models (FMs) for text and image generation, summarization, classification, open-ended Q\&A, information extraction, and text or image search. In this guide we'll look at how we can get started with Amazon Bedrock and Supabase Vector in Python using the Amazon Titan multimodal model and the [vecs client](/docs/guides/ai/vecs-python-client). You can find the full application code as a Python Poetry project on [GitHub](https://github.com/supabase/supabase/tree/master/examples/ai/aws_bedrock_image_search). ## Create a new Python project with Poetry [Poetry](https://python-poetry.org/) provides packaging and dependency management for Python. If you haven't already, install poetry via pip: ```shell pip install poetry ``` Then initialize a new project: ```shell poetry new aws_bedrock_image_search ``` ## Spin up a Postgres database with pgvector If you haven't already, head over to [database.new](https://database.new) and create a new project. Every Supabase project comes with a full Postgres database and the [pgvector extension](/docs/guides/database/extensions/pgvector) preconfigured. When creating your project, make sure to note down your database password as you will need it to construct the `DB_URL` in the next step. You can find the database connection string in your Supabase Dashboard [database settings](https://supabase.com/dashboard/project/_/settings/database). Select "Use connection pooling" with `Mode: Session` for a direct connection to your Postgres database. It will look something like this: ```txt postgresql://postgres.[PROJECT-REF]:[YOUR-PASSWORD]@aws-0-[REGION].pooler.supabase.com:5432/postgres ``` ## Install the dependencies We will need to add the following dependencies to our project: * [`vecs`](https://github.com/supabase/vecs#vecs): Supabase Vector Python Client. * [`boto3`](https://boto3.amazonaws.com/v1/documentation/api/latest/index.html): AWS SDK for Python. * [`matplotlib`](https://matplotlib.org/): for displaying our image result. ```shell poetry add vecs boto3 matplotlib ``` ## Import the necessary dependencies At the top of your main python script, import the dependencies and store your `DB URL` from above in a variable: ```python import sys import boto3 import vecs import json import base64 from matplotlib import pyplot as plt from matplotlib import image as mpimg from typing import Optional DB_CONNECTION = "postgresql://postgres.[PROJECT-REF]:[YOUR-PASSWORD]@aws-0-[REGION].pooler.supabase.com:5432/postgres" ``` Next, get the [credentials to your AWS account](https://boto3.amazonaws.com/v1/documentation/api/latest/guide/credentials.html) and instantiate the `boto3` client: ```python bedrock_client = boto3.client( 'bedrock-runtime', region_name='us-west-2', # Credentials from your AWS account aws_access_key_id='', aws_secret_access_key='', aws_session_token='', ) ``` ## Create embeddings for your images In the root of your project, create a new folder called `images` and add some images. You can use the images from the example project on [GitHub](https://github.com/supabase/supabase/tree/master/examples/ai/aws_bedrock_image_search/images) or you can find license free images on [Unsplash](https://unsplash.com). To send images to the Amazon Bedrock API we need to need to encode them as `base64` strings. Create the following helper methods: ```python def readFileAsBase64(file_path): """Encode image as base64 string.""" try: with open(file_path, "rb") as image_file: input_image = base64.b64encode(image_file.read()).decode("utf8") return input_image except: print("bad file name") sys.exit(0) def construct_bedrock_image_body(base64_string): """Construct the request body. https://docs.aws.amazon.com/bedrock/latest/userguide/model-parameters-titan-embed-mm.html """ return json.dumps( { "inputImage": base64_string, "embeddingConfig": {"outputEmbeddingLength": 1024}, } ) def get_embedding_from_titan_multimodal(body): """Invoke the Amazon Titan Model via API request.""" response = bedrock_client.invoke_model( body=body, modelId="amazon.titan-embed-image-v1", accept="application/json", contentType="application/json", ) response_body = json.loads(response.get("body").read()) print(response_body) return response_body["embedding"] def encode_image(file_path): """Generate embedding for the image at file_path.""" base64_string = readFileAsBase64(file_path) body = construct_bedrock_image_body(base64_string) emb = get_embedding_from_titan_multimodal(body) return emb ``` Next, create a `seed` method, which will create a new Supabase Vector Collection, generate embeddings for your images, and upsert the embeddings into your database: ```python def seed(): # create vector store client vx = vecs.create_client(DB_CONNECTION) # get or create a collection of vectors with 1024 dimensions images = vx.get_or_create_collection(name="image_vectors", dimension=1024) # Generate image embeddings with Amazon Titan Model img_emb1 = encode_image('./images/one.jpg') img_emb2 = encode_image('./images/two.jpg') img_emb3 = encode_image('./images/three.jpg') img_emb4 = encode_image('./images/four.jpg') # add records to the *images* collection images.upsert( records=[ ( "one.jpg", # the vector's identifier img_emb1, # the vector. list or np.array {"type": "jpg"} # associated metadata ), ( "two.jpg", img_emb2, {"type": "jpg"} ), ( "three.jpg", img_emb3, {"type": "jpg"} ), ( "four.jpg", img_emb4, {"type": "jpg"} ) ] ) print("Inserted images") # index the collection for fast search performance images.create_index() print("Created index") ``` Add this method as a script in your `pyproject.toml` file: ```toml [tool.poetry.scripts] seed = "image_search.main:seed" search = "image_search.main:search" ``` After activating the virtual environment with `poetry shell` you can now run your seed script via `poetry run seed`. You can inspect the generated embeddings in your Supabase Dashboard by visiting the [Table Editor](https://supabase.com/dashboard/project/_/editor), selecting the `vecs` schema, and the `image_vectors` table. ## Perform an image search from a text query We can use Supabase Vector to query our embeddings. We can either use an image as the search input or generate an embedding from a string input: ```python def search(query_term: Optional[str] = None): if query_term is None: query_term = sys.argv[1] # create vector store client vx = vecs.create_client(DB_CONNECTION) images = vx.get_or_create_collection(name="image_vectors", dimension=1024) # Encode text query text_emb = get_embedding_from_titan_multimodal(json.dumps( { "inputText": query_term, "embeddingConfig": {"outputEmbeddingLength": 1024}, } )) # query the collection filtering metadata for "type" = "jpg" results = images.query( data=text_emb, # required limit=1, # number of records to return filters={"type": {"$eq": "jpg"}}, # metadata filters ) result = results[0] print(result) plt.title(result) image = mpimg.imread('./images/' + result) plt.imshow(image) plt.show() ``` By limiting the query to one result, we can show the most relevant image to the user. Finally we use `matplotlib` to show the image result to the user. Go ahead and test it out by running `poetry run search` and you will be presented with an image of a "bike in front of a red brick wall". ## Conclusion With just a couple of lines of Python you are able to implement image search as well as reverse image search using the Amazon Titan multimodal model and Supabase Vector. # Going to Production Going to production checklist for AI applications. This guide will help you to prepare your application for production. We'll provide actionable steps to help you scale your application, ensure that it is reliable, can handle the load, and provide optimal accuracy for your use case. See our [Engineering for Scale](/docs/guides/ai/engineering-for-scale) guide for more information about engineering at scale. ## Do you need indexes? Sequential scans will result in significantly higher latencies and lower throughput, guaranteeing 100% accuracy and not being RAM bound. There are a couple of cases where you might not need indexes: * You have a small dataset and don't need to scale it. * You are not expecting high amounts of vector search queries per second. * You need to guarantee 100% accuracy. You don't have to create indexes in these cases and can use sequential scans instead. This type of workload will not be RAM bound and will not require any additional resources but will result in higher latencies and lower throughput. Extra CPU cores may help to improve queries per second, but it will not help to improve latency. On the other hand, if you need to scale your application, you will need to [create indexes](/docs/guides/ai/vector-indexes). This will result in lower latencies and higher throughput, but will require additional RAM to make use of Postgres Caching. Also, using indexes will result in lower accuracy, since you are replacing exact (KNN) search with approximate (ANN) search. ## HNSW vs IVFFlat indexes `pgvector` supports two types of indexes: HNSW and IVFFlat. We recommend using [HNSW](/docs/guides/ai/vector-indexes/hnsw-indexes) because of its [performance](https://supabase.com/blog/increase-performance-pgvector-hnsw#hnsw-performance-1536-dimensions) and [robustness against changing data](/docs/guides/ai/vector-indexes/hnsw-indexes#when-should-you-create-hnsw-indexes). ## HNSW, understanding `ef_construction`, `ef_search`, and `m` Index build parameters: * `m` is the number of bi-directional links created for every new element during construction. Higher `m` is suitable for datasets with high dimensionality and/or high accuracy requirements. Reasonable values for `m` are between 2 and 100. Range 12-48 is a good starting point for most use cases (16 is the default value). * `ef_construction` is the size of the dynamic list for the nearest neighbors (used during the construction algorithm). Higher `ef_construction` will result in better index quality and higher accuracy, but it will also increase the time required to build the index. `ef_construction` has to be at least 2 \* `m` (64 is the default value). At some point, increasing `ef_construction` does not improve the quality of the index. You can measure accuracy when `ef_search`=`ef_construction`: if accuracy is lower than 0.9, then there is room for improvement. Search parameters: * `ef_search` is the size of the dynamic list for the nearest neighbors (used during the search). Increasing `ef_search` will result in better accuracy, but it will also increase the time required to execute a query (40 is the default value). ## IVFFlat, understanding `probes` and `lists` Indexes used for approximate vector similarity search in pgvector divides a dataset into partitions. The number of these partitions is defined by the `lists` constant. The `probes` controls how many lists are going to be searched during a query. The values of lists and probes directly affect accuracy and queries per second (QPS). * Higher `lists` means an index will be built slower, but you can achieve better QPS and accuracy. * Higher `probes` means that select queries will be slower, but you can achieve better accuracy. * `lists` and `probes` are not independent. Higher `lists` means that you will have to use higher `probes` to achieve the same accuracy. You can find more examples of how `lists` and `probes` constants affect accuracy and QPS in [pgvector 0.4.0 performance](https://supabase.com/blog/pgvector-performance) blogpost. ## Performance tips when using indexes First, a few generic tips which you can pick and choose from: 1. The Supabase managed platform will automatically optimize Postgres configs for you based on your compute add-on. But if you self-host, consider **adjusting your Postgres config** based on RAM & CPU cores. See [example optimizations](https://gist.github.com/egor-romanov/323e2847851bbd758081511785573c08) for more details. 2. Prefer `inner-product` to `L2` or `Cosine` distances if your vectors are normalized (like `text-embedding-ada-002`). If embeddings are not normalized, `Cosine` distance should give the best results with an index. 3. **Pre-warm your database.** Implement the warm-up technique before transitioning to production or running benchmarks. * Use [pg\_prewarm](https://www.postgresql.org/docs/current/pgprewarm.html) to load the index into RAM `select pg_prewarm('vecs.docs_vec_idx');`. This will help to avoid cold cache issues. * Execute 10,000 to 50,000 "warm-up" queries before each benchmark/prod. This will help to utilize cache and buffers more efficiently. 4. **Establish your workload.** Fine-tune `m` and `ef_construction` or `lists` constants for the pgvector index to accelerate your queries (at the expense of a slower build times). For instance, for benchmarks with 1,000,000 OpenAI embeddings, we set `m` and `ef_construction` to 32 and 80, and it resulted in 35% higher QPS than 24 and 56 values respectively. 5. **Benchmark your own specific workloads.** Doing this during cache warm-up helps gauge the best value for the index build parameters, balancing accuracy with queries per second (QPS). ## Going into production 1. Decide if you are going to use indexes or not. You can skip the rest of this guide if you do not use indexes. 2. Over-provision RAM during preparation. You can scale down in step `5`, but it's better to start with a larger size to get the best results for RAM requirements. (We'd recommend at least 8XL if you're using Supabase.) 3. Upload your data to the database. If you use the [`vecs`](/docs/guides/ai/python/api) library, it will automatically generate an index with default parameters. 4. Run a benchmark using randomly generated queries and observe the results. Again, you can use the `vecs` library with the `ann-benchmarks` tool. Do it with default values for index build parameters, you can later adjust them to get the best results. 5. Monitor the RAM usage, and save it as a note for yourself. You would likely want to use a compute add-on in the future that has the same amount of RAM that was used at the moment (both actual RAM usage and RAM used for cache and buffers). 6. Scale down your compute add-on to the one that would have the same amount of RAM used at the moment. 7. Repeat step 3 to load the data into RAM. You should see QPS increase on subsequent runs, and stop when it no longer increases. 8. Run a benchmark using real queries and observe the results. You can use the `vecs` library for that as well with `ann-benchmarks` tool. Tweak `ef_search` for HNSW or `probes` for IVFFlat until you see that both accuracy and QPS match your requirements. 9. If you want higher QPS you can increase `m` and `ef_construction` for HNSW or `lists` for IVFFlat parameters (consider switching from IVF to HNSW). You have to rebuild the index with a higher `m` and `ef_construction` values and repeat steps 6-7 to find the best combination of `m`, `ef_construction` and `ef_search` constants to achieve the best QPS and accuracy values. Higher `m`, `ef_construction` mean that index will build slower, but you can achieve better QPS and accuracy. Higher `ef_search` mean that select queries will be slower, but you can achieve better accuracy. ## Useful links Don't forget to check out the general [Production Checklist](/docs/guides/platform/going-into-prod) to ensure your project is secure, performant, and will remain available for your users. You can look at our [Choosing Compute Add-on](/docs/guides/ai/choosing-compute-addon) guide to get a basic understanding of how much compute you might need for your workload. Or take a look at our [pgvector 0.5.0 performance](https://supabase.com/blog/increase-performance-pgvector-hnsw) and [pgvector 0.4.0 performance](https://supabase.com/blog/pgvector-performance) blog posts to see what pgvector is capable of and how the above technique can be used to achieve the best results. # Google Colab Use Google Colab to manage your Supabase Vector store. Google Colab is a hosted Jupyter Notebook service. It provides free access to computing resources, including GPUs and TPUs, and is well-suited to machine learning, data science, and education. We can use Colab to manage collections using [Supabase Vecs](/docs/guides/ai/vecs-python-client). In this tutorial we'll connect to a database running on the Supabase [platform](https://supabase.com/dashboard/). If you don't already have a database, you can create one here: [database.new](https://database.new). ## Create a new notebook Start by visiting [colab.research.google.com](https://colab.research.google.com/). There you can create a new notebook. ![Google Colab new notebook](/docs/img/ai/google-colab/colab-new.png) ## Install Vecs We'll use the Supabase Vector client, [Vecs](/docs/guides/ai/vecs-python-client), to manage our collections. At the top of the notebook add the notebook paste the following code and hit the "execute" button (`ctrl+enter`): ```py pip install vecs ``` ![Install vecs](/docs/img/ai/google-colab/install-vecs.png) ## Connect to your database Find the Postgres pooler connection string for your Supabase project in the [database settings](https://supabase.com/dashboard/project/_/settings/database) of the dashboard. Copy the "URI" format, which should look something like `postgres://postgres.xxxx:password@xxxx.pooler.supabase.com:6543/postgres` Create a new code block below the install block (`ctrl+m b`) and add the following code using the Postgres URI you copied above: ```py import vecs DB_CONNECTION = "postgres://postgres.xxxx:password@xxxx.pooler.supabase.com:6543/postgres" # create vector store client vx = vecs.create_client(DB_CONNECTION) ``` Execute the code block (`ctrl+enter`). If no errors were returned then your connection was successful. ## Create a collection Now we're going to create a new collection and insert some documents. Create a new code block below the install block (`ctrl+m b`). Add the following code to the code block and execute it (`ctrl+enter`): ```py collection = vx.get_or_create_collection(name="colab_collection", dimension=3) collection.upsert( vectors=[ ( "vec0", # the vector's identifier [0.1, 0.2, 0.3], # the vector. list or np.array {"year": 1973} # associated metadata ), ( "vec1", [0.7, 0.8, 0.9], {"year": 2012} ) ] ) ``` This will create a table inside your database within the `vecs` schema, called `colab_collection`. You can view the inserted items in the [Table Editor](https://supabase.com/dashboard/project/_/editor/), by selecting the `vecs` schema from the schema dropdown. ![Colab documents](/docs/img/ai/google-colab/colab-documents.png) ## Query your documents Now we can search for documents based on their similarity. Create a new code block and execute the following code: ```py collection.query( query_vector=[0.4,0.5,0.6], # required limit=5, # number of records to return filters={}, # metadata filters measure="cosine_distance", # distance measure to use include_value=False, # should distance measure values be returned? include_metadata=False, # should record metadata be returned? ) ``` You will see that this returns two documents in an array `['vec1', 'vec0']`: ![Colab results](/docs/img/ai/google-colab/colab-results.png) It also returns a warning: Query does not have a covering index for cosine_distance. You can lean more about creating indexes in the [Vecs documentation](https://supabase.github.io/vecs/api/#create-an-index). ## Resources * Vecs API: [supabase.github.io/vecs/api](https://supabase.github.io/vecs/api) # Hugging Face Inference API [Hugging Face](https://huggingface.co) is an open source hub for AI/ML models and tools. With over 100,000 machine learning models available, Hugging Face provides a great way to integrate specialized AI & ML tasks into your application. There are 3 ways to use Hugging Face models in your application: 1. Use the [Transformers](https://huggingface.co/docs/transformers/index) Python library to perform inference in a Python backend. 2. [Generate embeddings](/docs/guides/ai/quickstarts/generate-text-embeddings) directly in Edge Functions using Transformers.js. 3. Use Hugging Face's hosted [Inference API](https://huggingface.co/inference-api) to execute AI tasks remotely on Hugging Face servers. This guide will walk you through this approach. ## AI tasks Below are some of the types of tasks you can perform with Hugging Face: ### Natural language * [Summarization](https://huggingface.co/tasks/summarization) * [Text classification](https://huggingface.co/tasks/text-classification) * [Text generation](https://huggingface.co/tasks/text-generation) * [Translation](https://huggingface.co/tasks/translation) * [Fill in the blank](https://huggingface.co/tasks/fill-mask) ### Computer vision * [Image to text](https://huggingface.co/tasks/image-to-text) * [Text to image](https://huggingface.co/tasks/text-to-image) * [Image classification](https://huggingface.co/tasks/image-classification) * [Video classification](https://huggingface.co/tasks/video-classification) * [Object detection](https://huggingface.co/tasks/object-detection) * [Image segmentation](https://huggingface.co/tasks/image-segmentation) ### Audio * [Text to speech](https://huggingface.co/tasks/text-to-speech) * [Speech to text](https://huggingface.co/tasks/automatic-speech-recognition) * [Audio classification](https://huggingface.co/tasks/audio-classification) See a [full list of tasks](https://huggingface.co/tasks). ## Access token First generate a Hugging Face access token for your app: https://huggingface.co/settings/tokens Name your token based on the app its being used for and the environment. For example, if you are building an image generation app you might create 2 tokens: * "Image Generator (Dev)" * "Image Generator (Prod)" Since we will be using this token for the inference API, choose the `read` role. ## Edge Functions Edge Functions are server-side TypeScript functions that run on-demand. Since Edge Functions run on a server, you can safely give them access to your Hugging Face access token. To create a new Edge Function, navigate to your local project and initialize Supabase if you haven't already: ```shell supabase init ``` Then create an Edge Function: ```shell supabase functions new text-to-image ``` Create a file called `.env.local` to store your Hugging Face access token: ```shell HUGGING_FACE_ACCESS_TOKEN= ``` Let's modify the Edge Function to import Hugging Face's inference client and perform a `text-to-image` request: ```ts import { serve } from 'https://deno.land/std@0.168.0/http/server.ts' import { HfInference } from 'https://esm.sh/@huggingface/inference@2.3.2' const hf = new HfInference(Deno.env.get('HUGGING_FACE_ACCESS_TOKEN')) serve(async (req) => { const { prompt } = await req.json() const image = await hf.textToImage( { inputs: prompt, model: 'stabilityai/stable-diffusion-2', }, { use_cache: false, } ) return new Response(image) }) ``` 1. This function creates a new instance of `HfInference` using the `HUGGING_FACE_ACCESS_TOKEN` environment variable. 2. It expects a POST request that includes a JSON request body. The JSON body should include a parameter called `prompt` that represents the text-to-image prompt that we will pass to Hugging Face's inference API. 3. Next we call `textToImage()`, passing in the user's prompt along with the model that we would like to use for the image generation. Today Hugging Face recommends `stabilityai/stable-diffusion-2`, but you can change this to any other text-to-image model. You can see a list of which models are supported for each task by navigating to their [models page](https://huggingface.co/models?pipeline_tag=text-to-image) and filtering by task. 4. We set `use_cache` to `false` so that repeat queries with the same prompt will produce new images. If the task and model you are using is deterministic (will always produce the same result based on the same input), consider setting `use_cache` to `true` for faster responses. 5. The `image` result returned from the API will be a `Blob`. We can pass the `Blob` directly into a `new Response()` which will automatically set the content type and body of the response from the `image`. Finally let's serve the Edge Function locally to test it: ```shell supabase functions serve --env-file .env.local --no-verify-jwt ``` Remember to pass in the `.env.local` file using the `--env-file` parameter so that the Edge Function can access the `HUGGING_FACE_ACCESS_TOKEN`. At this point, you can make an API request to your Edge Function using your preferred frontend framework (Next.js, React, Expo, etc). We can also test from the terminal using `curl`: ```shell curl --output result.jpg --location --request POST 'http://localhost:54321/functions/v1/text-to-image' \ --header 'Content-Type: application/json' \ --data '{"prompt":"Llama wearing sunglasses"}' ``` In this example, your generated image will save to `result.jpg`: ## Next steps You can now create an Edge Function that invokes a Hugging Face task using your model of choice. Try running some other [AI tasks](#ai-tasks). ## Resources * Official [Hugging Face site](https://huggingface.co/). * Official [Hugging Face JS docs](https://huggingface.co/docs/huggingface.js). * [Generate image captions](/docs/guides/ai/examples/huggingface-image-captioning) using Hugging Face. # Hybrid search Combine keyword search with semantic search. Hybrid search combines [full text search](/docs/guides/ai/keyword-search) (searching by keyword) with [semantic search](/docs/guides/ai/semantic-search) (searching by meaning) to identify results that are both directly and contextually relevant to the user's query. ## Use cases for hybrid search Sometimes a single search method doesn't quite capture what a user is really looking for. For example, if a user searches for "Italian recipes with tomato sauce" on a cooking app, a keyword search would pull up recipes that specifically mention "Italian," "recipes," and "tomato sauce" in the text. However, it might miss out on dishes that are quintessentially Italian and use tomato sauce but don't explicitly label themselves with these words, or use variations like "pasta sauce" or "marinara." On the other hand, a semantic search might understand the culinary context and find recipes that match the intent, such as a traditional "Spaghetti Marinara," even if they don't match the exact keyword phrase. However, it could also suggest recipes that are contextually related but not what the user is looking for, like a "Mexican salsa" recipe, because it understands the context to be broadly about tomato-based sauces. Hybrid search combines the strengths of both these methods. It would ensure that recipes explicitly mentioning the keywords are prioritized, thus capturing direct hits that satisfy the keyword criteria. At the same time, it would include recipes identified through semantic understanding as being related in meaning or context, like different Italian dishes that traditionally use tomato sauce but might not have been tagged explicitly with the user's search terms. It identifies results that are both directly and contextually relevant to the user's query while ideally minimizing misses and irrelevant suggestions. ## When to consider hybrid search The decision to use hybrid search depends on what your users are looking for in your app. For a code repository where developers need to find exact lines of code or error messages, keyword search is likely ideal because it matches specific terms. In a mental health forum where users search for advice or experiences related to their feelings, semantic search may be better because it finds results based on the meaning of a query, not just specific words. For a shopping app where customers might search for specific product names yet also be open to related suggestions, hybrid search combines the best of both worlds - finding exact matches while also uncovering similar products based on the shopping context. ## How to combine search methods Hybrid search merges keyword search and semantic search, but how does this process work? First, each search method is executed separately. Keyword search, which involves searching by specific words or phrases present in the content, will yield its own set of results. Similarly, semantic search, which involves understanding the context or meaning behind the search query rather than the specific words used, will generate its own unique results. Now with these separate result lists available, the next step is to combine them into a single, unified list. This is achieved through a process known as “fusion”. Fusion takes the results from both search methods and merges them together based on a certain ranking or scoring system. This system may prioritize certain results based on factors like their relevance to the search query, their ranking in the individual lists, or other criteria. The result is a final list that integrates the strengths of both keyword and semantic search methods. ## Reciprocal Ranked Fusion (RRF) One of the most common fusion methods is Reciprocal Ranked Fusion (RRF). The key idea behind RRF is to give more weight to the top-ranked items in each individual result list when building the final combined list. In RRF, we iterate over each record and assign a score (noting that each record could exist in one or both lists). The score is calculated as 1 divided by that record's rank in each list, summed together between both lists. For example, if a record with an ID of `123` was ranked third in the keyword search and ninth in semantic search, it would receive a score of $$\dfrac + \dfrac = 0.444$$. If the record was found in only one list and not the other, it would receive a score of 0 for the other list. The records are then sorted by this score to create the final list. The items with the highest scores are ranked first, and lowest scores ranked last. This method ensures that items that are ranked high in multiple lists are given a high rank in the final list. It also ensures that items that are ranked high in only a few lists but low in others are not given a high rank in the final list. Placing the rank in the denominator when calculating score helps penalize the low ranking records. ### Smoothing constant `k` To prevent extremely high scores for items that are ranked first (since we're dividing by the rank), a `k` constant is often added to the denominator to smooth the score: $$\dfrac$$ This constant can be any positive number, but is typically small. A constant of 1 would mean that a record ranked first would have a score of $$\dfrac = 0.5$$ instead of $$1$$. This adjustment can help balance the influence of items that are ranked very high in individual lists when creating the final combined list. ## Hybrid search in Postgres Let's implement hybrid search in Postgres using `tsvector` (keyword search) and `pgvector` (semantic search). First we'll create a `documents` table to store the documents that we will search over. This is just an example - adjust this to match the structure of your application. ```sql create table documents ( id bigint primary key generated always as identity, content text, fts tsvector generated always as (to_tsvector('english', content)) stored, embedding vector(512) ); ``` The table contains 4 columns: * `id` is an auto-generated unique ID for the record. We'll use this later to match records when performing RRF. * `content` contains the actual text we will be searching over. * `fts` is an auto-generated `tsvector` column that is generated using the text in `content`. We will use this for [full text search](/docs/guides/database/full-text-search) (search by keyword). * `embedding` is a [vector column](/docs/guides/ai/vector-columns) that stores the vector generated from our embedding model. We will use this for [semantic search](/docs/guides/ai/semantic-search) (search by meaning). We chose 512 dimensions for this example, but adjust this to match the size of the embedding vectors generated from your preferred model. Next we'll create indexes on the `fts` and `embedding` columns so that their individual queries will remain fast at scale: ```sql -- Create an index for the full-text search create index on documents using gin(fts); -- Create an index for the semantic vector search create index on documents using hnsw (embedding vector_ip_ops); ``` For full text search we use a [generalized inverted (GIN) index](https://www.postgresql.org/docs/current/gin-intro.html) which is designed for handling composite values like those stored in a `tsvector`. For semantic vector search we use an [HNSW index](/docs/guides/ai/vector-indexes/hnsw-indexes), which is a high performing approximate nearest neighbor (ANN) search algorithm. Note that we are using the `vector_ip_ops` (inner product) operator with this index because we plan on using the inner product (`<#>`) operator later in our query. If you plan to use a different operator like cosine distance (`<=>`), be sure to update the index accordingly. For more information, see [distance operators](/docs/guides/ai/vector-indexes#distance-operators). Finally we'll create our `hybrid_search` function: ```sql create or replace function hybrid_search( query_text text, query_embedding vector(512), match_count int, full_text_weight float = 1, semantic_weight float = 1, rrf_k int = 50 ) returns setof documents language sql as $$ with full_text as ( select id, -- Note: ts_rank_cd is not indexable but will only rank matches of the where clause -- which shouldn't be too big row_number() over(order by ts_rank_cd(fts, websearch_to_tsquery(query_text)) desc) as rank_ix from documents where fts @@ websearch_to_tsquery(query_text) order by rank_ix limit least(match_count, 30) * 2 ), semantic as ( select id, row_number() over (order by embedding <#> query_embedding) as rank_ix from documents order by rank_ix limit least(match_count, 30) * 2 ) select documents.* from full_text full outer join semantic on full_text.id = semantic.id join documents on coalesce(full_text.id, semantic.id) = documents.id order by coalesce(1.0 / (rrf_k + full_text.rank_ix), 0.0) * full_text_weight + coalesce(1.0 / (rrf_k + semantic.rank_ix), 0.0) * semantic_weight desc limit least(match_count, 30) $$; ``` Let's break this down: * **Parameters:** The function accepts quite a few parameters, but the main (required) ones are `query_text`, `query_embedding`, and `match_count`. * `query_text` is the user's query text (more on this shortly) * `query_embedding` is the vector representation of the user's query produced by the embedding model. We chose 512 dimensions for this example, but adjust this to match the size of the embedding vectors generated from your preferred model. This must match the size of the `embedding` vector on the `documents` table (and use the same model). * `match_count` is the number of records returned in the `limit` clause. The other parameters are optional, but give more control over the fusion process. * `full_text_weight` and `semantic_weight` decide how much weight each search method gets in the final score. These are both 1 by default which means they both equally contribute towards the final rank. A `full_text_weight` of 2 and `semantic_weight` of 1 would give full-text search twice as much weight as semantic search. * `rrf_k` is the `k` [smoothing constant](#smoothing-constant-k) added to the reciprocal rank. The default is 50. * **Return type:** The function returns a set of records from our `documents` table. * **CTE:** We create two [common table expressions (CTE)](https://www.postgresql.org/docs/current/queries-with.html), one for full-text search and one for semantic search. These perform each query individually prior to joining them. * **RRF:** The final query combines the results from the two CTEs using [reciprocal rank fusion (RRF)](#reciprocal-ranked-fusion-rrf). ## Running hybrid search To use this function in SQL, we can run: ```sql select * from hybrid_search( 'Italian recipes with tomato sauce', -- user query '[...]'::vector(512), -- embedding generated from user query 10 ); ``` In practice, you will likely be calling this from the [Supabase client](/docs/reference/javascript/introduction) or through a custom backend layer. Here is a quick example of how you might call this from an [Edge Function](/docs/guides/functions) using JavaScript: ```tsx import { createClient } from 'jsr:@supabase/supabase-js@2' import OpenAI from 'npm:openai' const supabaseUrl = Deno.env.get('SUPABASE_URL')! const supabaseServiceRoleKey = Deno.env.get('SUPABASE_SERVICE_ROLE_KEY')! const openaiApiKey = Deno.env.get('OPENAI_API_KEY')! Deno.serve(async (req) => { // Grab the user's query from the JSON payload const { query } = await req.json() // Instantiate OpenAI client const openai = new OpenAI({ apiKey: openaiApiKey }) // Generate a one-time embedding for the user's query const embeddingResponse = await openai.embeddings.create({ model: 'text-embedding-3-large', input: query, dimensions: 512, }) const [{ embedding }] = embeddingResponse.data // Instantiate the Supabase client // (replace service role key with user's JWT if using Supabase auth and RLS) const supabase = createClient(supabaseUrl, supabaseServiceRoleKey) // Call hybrid_search Postgres function via RPC const { data: documents } = await supabase.rpc('hybrid_search', { query_text: query, query_embedding: embedding, match_count: 10, }) return new Response(JSON.stringify(documents), { headers: { 'Content-Type': 'application/json' }, }) }) ``` This uses OpenAI's `text-embedding-3-large` model to generate embeddings (shortened to 512 dimensions for faster retrieval). Swap in your preferred embedding model (and dimension size) accordingly. To test this, make a `POST` request to the function's endpoint while passing in a JSON payload containing the user's query. Here is an example `POST` request using cURL: ```tsx curl -i --location --request POST \ 'http://127.0.0.1:54321/functions/v1/hybrid-search' \ --header 'Authorization: Bearer ' \ --header 'Content-Type: application/json' \ --data '{"query":"Italian recipes with tomato sauce"}' ``` For more information on how to create, test, and deploy edge functions, see [Getting started](/docs/guides/functions/quickstart). ## See also * [Embedding concepts](/docs/guides/ai/concepts) * [Vector columns](/docs/guides/ai/vector-columns) * [Vector indexes](/docs/guides/ai/vector-indexes) * [Semantic search](/docs/guides/ai/semantic-search) * [Full text (keyword) search](/docs/guides/database/full-text-search) # Amazon Bedrock [Amazon Bedrock](https://aws.amazon.com/bedrock) is a fully managed service that offers a choice of high-performing foundation models (FMs) from leading AI companies like AI21 Labs, Anthropic, Cohere, Meta, Mistral AI, Stability AI, and Amazon. Each model is accessible through a common API which implements a broad set of features to help build generative AI applications with security, privacy, and responsible AI in mind. This guide will walk you through an example using Amazon Bedrock SDK with `vecs`. We will create embeddings using the Amazon Titan Embeddings G1 – Text v1.2 (amazon.titan-embed-text-v1) model, insert these embeddings into a Postgres database using vecs, and then query the collection to find the most similar sentences to a given query sentence. ## Create an environment First, you need to set up your environment. You will need Python 3.7+ with the `vecs` and `boto3` libraries installed. You can install the necessary Python libraries using pip: ```sh pip install vecs boto3 ``` You'll also need: * [Credentials to your AWS account](https://boto3.amazonaws.com/v1/documentation/api/latest/guide/credentials.html) * [A Postgres Database with the pgvector extension](hosting.md) ## Create embeddings Next, we will use Amazon’s Titan Embedding G1 - Text v1.2 model to create embeddings for a set of sentences. ```python import boto3 import vecs import json client = boto3.client( 'bedrock-runtime', region_name='us-east-1', # Credentials from your AWS account aws_access_key_id='', aws_secret_access_key='', aws_session_token='', ) dataset = [ "The cat sat on the mat.", "The quick brown fox jumps over the lazy dog.", "Friends, Romans, countrymen, lend me your ears", "To be or not to be, that is the question.", ] embeddings = [] for sentence in dataset: # invoke the embeddings model for each sentence response = client.invoke_model( body= json.dumps({"inputText": sentence}), modelId= "amazon.titan-embed-text-v1", accept = "application/json", contentType = "application/json" ) # collect the embedding from the response response_body = json.loads(response["body"].read()) # add the embedding to the embedding list embeddings.append((sentence, response_body.get("embedding"), {})) ``` ### Store the embeddings with vecs Now that we have our embeddings, we can insert them into a Postgres database using vecs. ```python import vecs DB_CONNECTION = "postgresql://:@:/" # create vector store client vx = vecs.Client(DB_CONNECTION) # create a collection named 'sentences' with 1536 dimensional vectors # to match the default dimension of the Titan Embeddings G1 - Text model sentences = vx.get_or_create_collection(name="sentences", dimension=1536) # upsert the embeddings into the 'sentences' collection sentences.upsert(records=embeddings) # create an index for the 'sentences' collection sentences.create_index() ``` ### Querying for most similar sentences Now, we query the `sentences` collection to find the most similar sentences to a sample query sentence. First need to create an embedding for the query sentence. Next, we query the collection we created earlier to find the most similar sentences. ```python query_sentence = "A quick animal jumps over a lazy one." # create vector store client vx = vecs.Client(DB_CONNECTION) # create an embedding for the query sentence response = client.invoke_model( body= json.dumps({"inputText": query_sentence}), modelId= "amazon.titan-embed-text-v1", accept = "application/json", contentType = "application/json" ) response_body = json.loads(response["body"].read()) query_embedding = response_body.get("embedding") # query the 'sentences' collection for the most similar sentences results = sentences.query( data=query_embedding, limit=3, include_value = True ) # print the results for result in results: print(result) ``` This returns the most similar 3 records and their distance to the query vector. ('The quick brown fox jumps over the lazy dog.', 0.27600620558852) ('The cat sat on the mat.', 0.609986272479202) ('To be or not to be, that is the question.', 0.744849503688346) ## Resources * [Amazon Bedrock](https://aws.amazon.com/bedrock) * [Amazon Titan](https://aws.amazon.com/bedrock/titan) * [Semantic Image Search with Amazon Titan](/docs/guides/ai/examples/semantic-image-search-amazon-titan) # Learn how to integrate Supabase with LlamaIndex, a data framework for your LLM applications. Learn how to integrate Supabase with LlamaIndex, a data framework for your LLM applications. This guide will walk you through a basic example using the LlamaIndex [`SupabaseVectorStore`](https://github.com/supabase/supabase/blob/master/examples/ai/llamaindex/llamaindex.ipynb). ## Launching a notebook Launch our [LlamaIndex](https://github.com/supabase/supabase/blob/master/examples/ai/llamaindex/llamaindex.ipynb) notebook in Colab: At the top of the notebook, you'll see a button `Copy to Drive`. Click this button to copy the notebook to your Google Drive. ## Fill in your OpenAI credentials Inside the Notebook, add your `OPENAI_API_KEY` key. Find the cell which contains this code: ```py import os os.environ['OPENAI_API_KEY'] = "[your_openai_api_key]" ``` ## Connecting to your database Inside the Notebook, find the cell which specifies the `DB_CONNECTION`. It will contain some code like this: ```python DB_CONNECTION = "postgresql://:@:/" # create vector store client vx = vecs.create_client(DB_CONNECTION) ``` Replace the `DB_CONNECTION` with your own connection string for your database. You can find the Postgres connection string in the [Database Settings](https://supabase.com/dashboard/project/_/settings/database) of your Supabase project. ## Stepping through the notebook Now all that's left is to step through the notebook. You can do this by clicking the "execute" button (`ctrl+enter`) at the top left of each code cell. The notebook guides you through the process of creating a collection, adding data to it, and querying it. You can view the inserted items in the [Table Editor](https://supabase.com/dashboard/project/_/editor/), by selecting the `vecs` schema from the schema dropdown. ![Colab documents](/docs/img/ai/google-colab/colab-documents.png) ## Resources * Visit the LlamaIndex + `SupabaseVectorStore` [docs](https://gpt-index.readthedocs.io/en/latest/examples/vector_stores/SupabaseVectorIndexDemo.html) * Visit the official LlamaIndex [repo](https://github.com/jerryjliu/llama_index/) # Roboflow Learn how to integrate Supabase with Roboflow, a tool for running fine-tuned and foundation vision models. In this guide, we will walk through two examples of using [Roboflow Inference](https://inference.roboflow.com) to run fine-tuned and foundation models. We will run inference and save predictions using an object detection model and [CLIP](https://github.com/openai/CLIP). ## Save computer vision predictions Once you have a trained vision model, you need to create business logic for your application. In many cases, you want to save inference results to a file. The steps below show you how to run a vision model locally and save predictions to Supabase. ### Preparation: Set up a model Before you begin, you will need an object detection model trained on your data. You can [train a model on Roboflow](https://blog.roboflow.com/getting-started-with-roboflow/), leveraging end-to-end tools from data management and annotation to deployment, or [upload custom model weights](https://docs.roboflow.com/deploy/upload-custom-weights) for deployment. All models have an infinitely scalable API through which you can query your model, and can be run locally. For this guide, we will use a demo [rock, paper, scissors](https://universe.roboflow.com/roboflow-58fyf/rock-paper-scissors-sxsw) model. ### Step 1: Install and start Roboflow Inference You will deploy our model locally using Roboflow Inference, a computer vision inference server. To install and start Roboflow Inference, first install Docker on your machine. Then, run: pip install inference inference-cli inference-sdk && inference server start An inference server will be available at `http://localhost:9001`. ### Step 2: Run inference on an image You can run inference on images and videos. Let's run inference on an image. Create a new Python file and add the following code: ```python from inference_sdk import InferenceHTTPClient image = "example.jpg" MODEL_ID = "rock-paper-scissors-sxsw/11" client = InferenceHTTPClient( api_url="http://localhost:9001", api_key="ROBOFLOW_API_KEY" ) with client.use_model(MODEL_ID): predictions = client.infer(image) print(predictions) ``` Above, replace: 1. The image URL with the name of the image on which you want to run inference. 2. `ROBOFLOW_API_KEY` with your Roboflow API key. [Learn how to retrieve your Roboflow API key](https://docs.roboflow.com/api-reference/authentication#retrieve-an-api-key). 3. `MODEL_ID` with your Roboflow model ID. [Learn how to retrieve your model ID](https://docs.roboflow.com/api-reference/workspace-and-project-ids). When you run the code above, a list of predictions will be printed to the console: {'time': 0.05402109300121083, 'image': {'width': 640, 'height': 480}, 'predictions': [{'x': 312.5, 'y': 392.0, 'width': 255.0, 'height': 110.0, 'confidence': 0.8620790839195251, 'class': 'Paper', 'class_id': 0}]} ### Step 3: Save results in Supabase To save results in Supabase, add the following code to your script: ```python import os from supabase import create_client, Client url: str = os.environ.get("SUPABASE_URL") key: str = os.environ.get("SUPABASE_KEY") supabase: Client = create_client(url, key) result = supabase.table('predictions') \ .insert({"filename": image, "predictions": predictions}) \ .execute() ``` You can then query your predictions using the following code: ```python result = supabase.table('predictions') \ .select("predictions") \ .filter("filename", "eq", image) \ .execute() print(result) ``` Here is an example result: data=[{'predictions': {'time': 0.08492901099998562, 'image': {'width': 640, 'height': 480}, 'predictions': [{'x': 312.5, 'y': 392.0, 'width': 255.0, 'height': 110.0, 'confidence': 0.8620790839195251, 'class': 'Paper', 'class_id': 0}]}}, {'predictions': {'time': 0.08818970100037404, 'image': {'width': 640, 'height': 480}, 'predictions': [{'x': 312.5, 'y': 392.0, 'width': 255.0, 'height': 110.0, 'confidence': 0.8620790839195251, 'class': 'Paper', 'class_id': 0}]}}] count=None ## Calculate and save CLIP embeddings You can use the Supabase vector database functionality to store and query CLIP embeddings. Roboflow Inference provides a HTTP interface through which you can calculate image and text embeddings using CLIP. ### Step 1: Install and start Roboflow Inference See [Step #1: Install and Start Roboflow Inference](#step-1-install-and-start-roboflow-inference) above to install and start Roboflow Inference. ### Step 2: Run CLIP on an image Create a new Python file and add the following code: ```python import cv2 import supervision as sv import requests import base64 import os IMAGE_DIR = "images/train/images/" API_KEY = "" SERVER_URL = "http://localhost:9001" results = [] for i, image in enumerate(os.listdir(IMAGE_DIR)): print(f"Processing image {image}") infer_clip_payload = { "image": { "type": "base64", "value": base64.b64encode(open(IMAGE_DIR + image, "rb").read()).decode("utf-8"), }, } res = requests.post( f"{SERVER_URL}/clip/embed_image?api_key={API_KEY}", json=infer_clip_payload, ) embeddings = res.json()['embeddings'] results.append({ "filename": image, "embeddings": embeddings }) ``` This code will calculate CLIP embeddings for each image in the directory and print the results to the console. Above, replace: 1. `IMAGE_DIR` with the directory containing the images on which you want to run inference. 2. `ROBOFLOW_API_KEY` with your Roboflow API key. [Learn how to retrieve your Roboflow API key](https://docs.roboflow.com/api-reference/authentication#retrieve-an-api-key). You can also calculate CLIP embeddings in the cloud by setting `SERVER_URL` to `https://infer.roboflow.com`. ### Step 3: Save embeddings in Supabase You can store your image embeddings in Supabase using the Supabase `vecs` Python package: First, install `vecs`: pip install vecs Next, add the following code to your script to create an index: ```python import vecs DB_CONNECTION = "postgresql://postgres:[password]@[host]:[port]/[database]" vx = vecs.create_client(DB_CONNECTION) # create a collection of vectors with 3 dimensions images = vx.get_or_create_collection(name="image_vectors", dimension=512) for result in results: image = result["filename"] embeddings = result["embeddings"][0] # insert a vector into the collection images.upsert( records=[ ( image, embeddings, {} # metadata ) ] ) images.create_index() ``` Replace `DB_CONNECTION` with the authentication information for your database. You can retrieve this from the Supabase dashboard in `Project Settings > Database Settings`. You can then query your embeddings using the following code: ```python infer_clip_payload = { "text": "cat", } res = requests.post( f"{SERVER_URL}/clip/embed_text?api_key={API_KEY}", json=infer_clip_payload, ) embeddings = res.json()['embeddings'] result = images.query( data=embeddings[0], limit=1 ) print(result[0]) ``` ## Resources * [Roboflow Inference documentation](https://inference.roboflow.com) * [Roboflow Getting Started guide](https://blog.roboflow.com/getting-started-with-roboflow/) * [How to Build a Semantic Image Search Engine with Supabase and OpenAI CLIP](https://blog.roboflow.com/how-to-use-semantic-search-supabase-openai-clip/) # Keyword search Learn how to search by words or phrases. Keyword search involves locating documents or records that contain specific words or phrases, primarily based on the exact match between the search terms and the text within the data. It differs from [semantic search](/docs/guides/ai/semantic-search), which interprets the meaning behind the query to provide results that are contextually related, even if the exact words aren't present in the text. Semantic search considers synonyms, intent, and natural language nuances to provide a more nuanced approach to information retrieval. In Postgres, keyword search is implemented using [full-text search](/docs/guides/database/full-text-search). It supports indexing and text analysis for data retrieval, focusing on records that match the search criteria. Postgres' full-text search extends beyond simple keyword matching to address linguistic nuances, making it effective for applications that require precise text queries. ## When and why to use keyword search Keyword search is particularly useful in scenarios where precision and specificity matter. It's more effective than semantic search when users are looking for information using exact terminology or specific identifiers. It ensures that results directly contain those terms, reducing the chance of retrieving irrelevant information that might be semantically related but not what the user seeks. For example in technical or academic research databases, researchers often search for specific studies, compounds, or concepts identified by certain terms or codes. Searching for a specific chemical compound using its exact molecular formula or a unique identifier will yield more focused and relevant results compared to a semantic search, which could return a wide range of documents discussing the compound in different contexts. Keyword search ensures documents that explicitly mention the exact term are found, allowing users to access the precise data they need efficiently. It's also possible to combine keyword search with semantic search to get the best of both worlds. See [Hybrid search](/docs/guides/ai/hybrid-search) for more details. ## Using full-text search For an in-depth guide to Postgres' full-text search, including how to store, index, and query records, see [Full text search](/docs/guides/database/full-text-search). ## See also * [Semantic search](/docs/guides/ai/semantic-search) * [Hybrid search](/docs/guides/ai/hybrid-search) # LangChain [LangChain](https://langchain.com/) is a popular framework for working with AI, Vectors, and embeddings. LangChain supports using Supabase as a [vector store](https://js.langchain.com/docs/modules/indexes/vector_stores/integrations/supabase), using the `pgvector` extension. ## Initializing your database Prepare you database with the relevant tables: ## Usage You can now search your documents using any Node.js application. This is intended to be run on a secure server route. ```js import { SupabaseVectorStore } from 'langchain/vectorstores/supabase' import { OpenAIEmbeddings } from 'langchain/embeddings/openai' import { createClient } from '@supabase/supabase-js' const supabaseKey = process.env.SUPABASE_SERVICE_ROLE_KEY if (!supabaseKey) throw new Error(`Expected SUPABASE_SERVICE_ROLE_KEY`) const url = process.env.SUPABASE_URL if (!url) throw new Error(`Expected env var SUPABASE_URL`) export const run = async () => { const client = createClient(url, supabaseKey) const vectorStore = await SupabaseVectorStore.fromTexts( ['Hello world', 'Bye bye', "What's this?"], [{ id: 2 }, { id: 1 }, { id: 3 }], new OpenAIEmbeddings(), { client, tableName: 'documents', queryName: 'match_documents', } ) const resultOne = await vectorStore.similaritySearch('Hello world', 1) console.log(resultOne) } ``` ### Simple metadata filtering Given the above `match_documents` Postgres function, you can also pass a filter parameter to only return documents with a specific metadata field value. This filter parameter is a JSON object, and the `match_documents` function will use the Postgres JSONB Containment operator `@>` to filter documents by the metadata field values you specify. See details on the [Postgres JSONB Containment operator](https://www.postgresql.org/docs/current/datatype-json.html#JSON-CONTAINMENT) for more information. ```js import { SupabaseVectorStore } from 'langchain/vectorstores/supabase' import { OpenAIEmbeddings } from 'langchain/embeddings/openai' import { createClient } from '@supabase/supabase-js' // First, follow set-up instructions above const privateKey = process.env.SUPABASE_SERVICE_ROLE_KEY if (!privateKey) throw new Error(`Expected env var SUPABASE_SERVICE_ROLE_KEY`) const url = process.env.SUPABASE_URL if (!url) throw new Error(`Expected env var SUPABASE_URL`) export const run = async () => { const client = createClient(url, privateKey) const vectorStore = await SupabaseVectorStore.fromTexts( ['Hello world', 'Hello world', 'Hello world'], [{ user_id: 2 }, { user_id: 1 }, { user_id: 3 }], new OpenAIEmbeddings(), { client, tableName: 'documents', queryName: 'match_documents', } ) const result = await vectorStore.similaritySearch('Hello world', 1, { user_id: 3, }) console.log(result) } ``` ### Advanced metadata filtering You can also use query builder-style filtering ([similar to how the Supabase JavaScript library works](https://supabase.com/docs/reference/javascript/using-filters)) instead of passing an object. Note that since the filter properties will be in the metadata column, you need to use arrow operators (`->` for integer or `->>` for text) as defined in [PostgREST API documentation](https://postgrest.org/en/stable/references/api/tables_views.html?highlight=operators#json-columns) and specify the data type of the property (e.g. the column should look something like `metadata->some_int_value::int`). ```js import { SupabaseFilterRPCCall, SupabaseVectorStore } from 'langchain/vectorstores/supabase' import { OpenAIEmbeddings } from 'langchain/embeddings/openai' import { createClient } from '@supabase/supabase-js' // First, follow set-up instructions above const privateKey = process.env.SUPABASE_SERVICE_ROLE_KEY if (!privateKey) throw new Error(`Expected env var SUPABASE_SERVICE_ROLE_KEY`) const url = process.env.SUPABASE_URL if (!url) throw new Error(`Expected env var SUPABASE_URL`) export const run = async () => { const client = createClient(url, privateKey) const embeddings = new OpenAIEmbeddings() const store = new SupabaseVectorStore(embeddings, { client, tableName: 'documents', }) const docs = [ { pageContent: 'This is a long text, but it actually means something because vector database does not understand Lorem Ipsum. So I would need to expand upon the notion of quantum fluff, a theoretical concept where subatomic particles coalesce to form transient multidimensional spaces. Yet, this abstraction holds no real-world application or comprehensible meaning, reflecting a cosmic puzzle.', metadata: { b: 1, c: 10, stuff: 'right' }, }, { pageContent: 'This is a long text, but it actually means something because vector database does not understand Lorem Ipsum. So I would need to proceed by discussing the echo of virtual tweets in the binary corridors of the digital universe. Each tweet, like a pixelated canary, hums in an unseen frequency, a fascinatingly perplexing phenomenon that, while conjuring vivid imagery, lacks any concrete implication or real-world relevance, portraying a paradox of multidimensional spaces in the age of cyber folklore.', metadata: { b: 2, c: 9, stuff: 'right' }, }, { pageContent: 'hello', metadata: { b: 1, c: 9, stuff: 'right' } }, { pageContent: 'hello', metadata: { b: 1, c: 9, stuff: 'wrong' } }, { pageContent: 'hi', metadata: { b: 2, c: 8, stuff: 'right' } }, { pageContent: 'bye', metadata: { b: 3, c: 7, stuff: 'right' } }, { pageContent: "what's this", metadata: { b: 4, c: 6, stuff: 'right' } }, ] await store.addDocuments(docs) const funcFilterA: SupabaseFilterRPCCall = (rpc) => rpc .filter('metadata->b::int', 'lt', 3) .filter('metadata->c::int', 'gt', 7) .textSearch('content', `'multidimensional' & 'spaces'`, { config: 'english', }) const resultA = await store.similaritySearch('quantum', 4, funcFilterA) const funcFilterB: SupabaseFilterRPCCall = (rpc) => rpc .filter('metadata->b::int', 'lt', 3) .filter('metadata->c::int', 'gt', 7) .filter('metadata->>stuff', 'eq', 'right') const resultB = await store.similaritySearch('hello', 2, funcFilterB) console.log(resultA, resultB) } ``` ## Hybrid search LangChain supports the concept of a hybrid search, which combines Similarity Search with Full Text Search. Read the official docs to get started: [Supabase Hybrid Search](https://js.langchain.com/docs/modules/indexes/retrievers/supabase-hybrid). You can install the LangChain Hybrid Search function though our [database.dev package manager](https://database.dev/langchain/hybrid_search). ## Resources * Official [LangChain site](https://langchain.com/). * Official [LangChain docs](https://js.langchain.com/docs/modules/indexes/vector_stores/integrations/supabase). * Supabase [Hybrid Search](https://js.langchain.com/docs/modules/indexes/retrievers/supabase-hybrid). # Choosing a Client As described in [Structured & Unstructured Embeddings](/docs/guides/ai/structured-unstructured), AI workloads come in many forms. For data science or ephemeral workloads, the [Supabase Vecs](https://supabase.github.io/vecs/) client gets you started quickly. All you need is a connection string and vecs handles setting up your database to store and query vectors with associated metadata. For production python applications with version controlled migrations, we recommend adding first class vector support to your toolchain by [registering the vector type with your ORM](https://github.com/pgvector/pgvector-python). pgvector provides bindings for the most commonly used SQL drivers/libraries including Django, SQLAlchemy, SQLModel, psycopg, asyncpg and Peewee. # Face similarity search Identify the celebrities who look most similar to you using Supabase Vecs. This guide will walk you through a ["Face Similarity Search"](https://github.com/supabase/supabase/blob/master/examples/ai/face_similarity.ipynb) example using Colab and Supabase Vecs. You will be able to identify the celebrities who look most similar to you (or any other person). You will: 1. Launch a Postgres database that uses pgvector to store embeddings 2. Launch a notebook that connects to your database 3. Load the "`ashraq/tmdb-people-image`" celebrity dataset 4. Use the `face_recognition` model to create an embedding for every celebrity photo. 5. Search for similar faces inside the dataset. ## Launching a notebook Launch our [`semantic_text_deduplication`](https://github.com/supabase/supabase/blob/master/examples/ai/face_similarity.ipynb) notebook in Colab: At the top of the notebook, you'll see a button `Copy to Drive`. Click this button to copy the notebook to your Google Drive. ## Connecting to your database Inside the Notebook, find the cell which specifies the `DB_CONNECTION`. It will contain some code like this: ```python import vecs DB_CONNECTION = "postgresql://:@:/" # create vector store client vx = vecs.create_client(DB_CONNECTION) ``` Replace the `DB_CONNECTION` with your own connection string for your database. You can find the Postgres connection string in the [Database Settings](https://supabase.com/dashboard/project/_/settings/database) of your Supabase project. ## Stepping through the notebook Now all that's left is to step through the notebook. You can do this by clicking the "execute" button (`ctrl+enter`) at the top left of each code cell. The notebook guides you through the process of creating a collection, adding data to it, and querying it. You can view the inserted items in the [Table Editor](https://supabase.com/dashboard/project/_/editor/), by selecting the `vecs` schema from the schema dropdown. ![Colab documents](/docs/img/ai/google-colab/colab-documents.png) ## Next steps You can now start building your own applications with Vecs. Check our [examples](/docs/guides/ai#examples) for ideas. # Generate Embeddings Generate text embeddings using Edge Functions. This guide will walk you through how to generate high quality text embeddings in [Edge Functions](/docs/guides/functions) using its built-in AI inference API, so no external API is required. ## Build the Edge Function Let's build an Edge Function that will accept an input string and generate an embedding for it. Edge Functions are server-side TypeScript HTTP endpoints that run on-demand closest to your users. ## Next steps * Learn more about [embedding concepts](/docs/guides/ai/concepts) * [Store your embeddings](/docs/guides/ai/vector-columns) in a database # Creating and managing collections Connecting to your database with Colab. This guide will walk you through a basic ["Hello World"](https://github.com/supabase/supabase/blob/master/examples/ai/vector_hello_world.ipynb) example using Colab and Supabase Vecs. You'll learn how to: 1. Launch a Postgres database that uses pgvector to store embeddings 2. Launch a notebook that connects to your database 3. Create a vector collection 4. Add data to the collection 5. Query the collection ## Launching a notebook Launch our [`vector_hello_world`](https://github.com/supabase/supabase/blob/master/examples/ai/vector_hello_world.ipynb) notebook in Colab: At the top of the notebook, you'll see a button `Copy to Drive`. Click this button to copy the notebook to your Google Drive. ## Connecting to your database Inside the Notebook, find the cell which specifies the `DB_CONNECTION`. It will contain some code like this: ```python import vecs DB_CONNECTION = "postgresql://:@:/" # create vector store client vx = vecs.create_client(DB_CONNECTION) ``` Replace the `DB_CONNECTION` with your own connection string for your database. You can find the Postgres connection string in the [Database Settings](https://supabase.com/dashboard/project/_/settings/database) of your Supabase project. ## Stepping through the notebook Now all that's left is to step through the notebook. You can do this by clicking the "execute" button (`ctrl+enter`) at the top left of each code cell. The notebook guides you through the process of creating a collection, adding data to it, and querying it. You can view the inserted items in the [Table Editor](https://supabase.com/dashboard/project/_/editor/), by selecting the `vecs` schema from the schema dropdown. ![Colab documents](/docs/img/ai/google-colab/colab-documents.png) ## Next steps You can now start building your own applications with Vecs. Check our [examples](/docs/guides/ai#examples) for ideas. # Semantic Text Deduplication Finding duplicate movie reviews with Supabase Vecs. This guide will walk you through a ["Semantic Text Deduplication"](https://github.com/supabase/supabase/blob/master/examples/ai/semantic_text_deduplication.ipynb) example using Colab and Supabase Vecs. You'll learn how to find similar movie reviews using embeddings, and remove any that seem like duplicates. You will: 1. Launch a Postgres database that uses pgvector to store embeddings 2. Launch a notebook that connects to your database 3. Load the IMDB dataset 4. Use the `sentence-transformers/all-MiniLM-L6-v2` model to create an embedding representing the semantic meaning of each review. 5. Search for all duplicates. ## Launching a notebook Launch our [`semantic_text_deduplication`](https://github.com/supabase/supabase/blob/master/examples/ai/semantic_text_deduplication.ipynb) notebook in Colab: At the top of the notebook, you'll see a button `Copy to Drive`. Click this button to copy the notebook to your Google Drive. ## Connecting to your database Inside the Notebook, find the cell which specifies the `DB_CONNECTION`. It will contain some code like this: ```python import vecs DB_CONNECTION = "postgresql://:@:/" # create vector store client vx = vecs.create_client(DB_CONNECTION) ``` Replace the `DB_CONNECTION` with your own connection string for your database. You can find the Postgres connection string in the [Database Settings](https://supabase.com/dashboard/project/_/settings/database) of your Supabase project. ## Stepping through the notebook Now all that's left is to step through the notebook. You can do this by clicking the "execute" button (`ctrl+enter`) at the top left of each code cell. The notebook guides you through the process of creating a collection, adding data to it, and querying it. You can view the inserted items in the [Table Editor](https://supabase.com/dashboard/project/_/editor/), by selecting the `vecs` schema from the schema dropdown. ![Colab documents](/docs/img/ai/google-colab/colab-documents.png) ## Next steps You can now start building your own applications with Vecs. Check our [examples](/docs/guides/ai#examples) for ideas. # RAG with Permissions Fine-grain access control with Retrieval Augmented Generation. Since pgvector is built on top of Postgres, you can implement fine-grain access control on your vector database using [Row Level Security (RLS)](/docs/guides/database/postgres/row-level-security). This means you can restrict which documents are returned during a vector similarity search to users that have access to them. Supabase also supports [Foreign Data Wrappers (FDW)](/docs/guides/database/extensions/wrappers/overview) which means you can use an external database or data source to determine these permissions if your user data doesn't exist in Supabase. Use this guide to learn how to restrict access to documents when performing retrieval augmented generation (RAG). ## Example In a typical RAG setup, your documents are chunked into small subsections and similarity is performed over those sections: ```sql -- Track documents/pages/files/etc create table documents ( id bigint primary key generated always as identity, name text not null, owner_id uuid not null references auth.users (id) default auth.uid(), created_at timestamp with time zone not null default now() ); -- Store the content and embedding vector for each section in the document -- with a reference to original document (one-to-many) create table document_sections ( id bigint primary key generated always as identity, document_id bigint not null references documents (id), content text not null, embedding vector (384) ); ``` Notice how we record the `owner_id` on each document. Let's create an RLS policy that restricts access to `document_sections` based on whether or not they own the linked document: ```sql -- enable row level security alter table document_sections enable row level security; -- setup RLS for select operations create policy "Users can query their own document sections" on document_sections for select to authenticated using ( document_id in ( select id from documents where (owner_id = (select auth.uid())) ) ); ``` Now every `select` query executed on `document_sections` will implicitly filter the returned sections based on whether or not the current user has access to them. For example, executing: ```sql select * from document_sections; ``` as an authenticated user will only return rows that they are the owner of (as determined by the linked document). More importantly, semantic search over these sections (or any additional filtering for that matter) will continue to respect these RLS policies: ```sql -- Perform inner product similarity based on a match_threshold select * from document_sections where document_sections.embedding <#> embedding < -match_threshold order by document_sections.embedding <#> embedding; ``` The above example only configures `select` access to users. If you wanted, you could create more RLS policies for inserts, updates, and deletes in order to apply the same permission logic for those other operations. See [Row Level Security](/docs/guides/database/postgres/row-level-security) for a more in-depth guide on RLS policies. ## Alternative scenarios Every app has its own unique requirements and may differ from the above example. Here are some alternative scenarios we often see and how they are implemented in Supabase. ### Documents owned by multiple people Instead of a one-to-many relationship between `users` and `documents`, you may require a many-to-many relationship so that multiple people can access the same document. Let's reimplement this using a join table: ```sql create table document_owners ( id bigint primary key generated always as identity, owner_id uuid not null references auth.users (id) default auth.uid(), document_id bigint not null references documents (id) ); ``` Then your RLS policy would change to: ```sql create policy "Users can query their own document sections" on document_sections for select to authenticated using ( document_id in ( select document_id from document_owners where (owner_id = (select auth.uid())) ) ); ``` Instead of directly querying the `documents` table, we query the join table. ### User and document data live outside of Supabase You may have an existing system that stores users, documents, and their permissions in a separate database. Let's explore the scenario where this data exists in another Postgres database. We'll use a foreign data wrapper (FDW) to connect to the external DB from within your Supabase DB: Let's assume your external DB contains a `users` and `documents` table like this: ```sql create table public.users ( id bigint primary key generated always as identity, email text not null, created_at timestamp with time zone not null default now() ); create table public.documents ( id bigint primary key generated always as identity, name text not null, owner_id bigint not null references public.users (id), created_at timestamp with time zone not null default now() ); ``` In your Supabase DB, let's create foreign tables that link to the above tables: ```sql create schema external; create extension postgres_fdw with schema extensions; -- Setup the foreign server create server foreign_server foreign data wrapper postgres_fdw options (host '', port '', dbname ''); -- Map local 'authenticated' role to external 'postgres' user create user mapping for authenticated server foreign_server options (user 'postgres', password ''); -- Import foreign 'users' and 'documents' tables into 'external' schema import foreign schema public limit to (users, documents) from server foreign_server into external; ``` We'll store `document_sections` and their embeddings in Supabase so that we can perform similarity search over them via pgvector. ```sql create table document_sections ( id bigint primary key generated always as identity, document_id bigint not null, content text not null, embedding vector (384) ); ``` We maintain a reference to the foreign document via `document_id`, but without a foreign key reference since foreign keys can only be added to local tables. Be sure to use the same ID data type that you use on your external documents table. Since we're managing users and authentication outside of Supabase, we have two options: 1. Make a direct Postgres connection to the Supabase DB and set the current user every request 2. Issue a custom JWT from your system and use it to authenticate with the REST API #### Direct Postgres connection You can directly connect to your Supabase Postgres DB using the [connection info](/dashboard/project/_/settings/database) on your project's database settings page. To use RLS with this method, we use a custom session variable that contains the current user's ID: ```sql -- enable row level security alter table document_sections enable row level security; -- setup RLS for select operations create policy "Users can query their own document sections" on document_sections for select to authenticated using ( document_id in ( select id from external.documents where owner_id = current_setting('app.current_user_id')::bigint ) ); ``` The session variable is accessed through the `current_setting()` function. We name the variable `app.current_user_id` here, but you can modify this to any name you like. We also cast it to a `bigint` since that was the data type of the `user.id` column. Change this to whatever data type you use for your ID. Now for every request, we set the user's ID at the beginning of the session: ```sql set app.current_user_id = ''; ``` Then all subsequent queries will inherit the permission of that user: ```sql -- Only document sections owned by the user are returned select * from document_sections where document_sections.embedding <#> embedding < -match_threshold order by document_sections.embedding <#> embedding; ``` #### Custom JWT with REST API If you would like to use the auto-generated REST API to query your Supabase database using JWTs from an external auth provider, you can get your auth provider to issue a custom JWT for Supabase. See the [Clerk Supabase docs](https://clerk.com/docs/integrations/databases/supabase) for an example of how this can be done. Modify the instructions to work with your own auth provider as needed. Now we can use the same RLS policy from our first example: ```sql -- enable row level security alter table document_sections enable row level security; -- setup RLS for select operations create policy "Users can query their own document sections" on document_sections for select to authenticated using ( document_id in ( select id from documents where (owner_id = (select auth.uid())) ) ); ``` Under the hood, `auth.uid()` references `current_setting('request.jwt.claim.sub')` which corresponds to the JWT's `sub` (subject) claim. This setting is automatically set at the beginning of each request to the REST API. All subsequent queries will inherit the permission of that user: ```sql -- Only document sections owned by the user are returned select * from document_sections where document_sections.embedding <#> embedding < -match_threshold order by document_sections.embedding <#> embedding; ``` ### Other scenarios There are endless approaches to this problem based on the complexities of each system. Luckily Postgres comes with all the primitives needed to provide access control in the way that works best for your project. If the examples above didn't fit your use case or you need to adjust them slightly to better fit your existing system, feel free to reach out to [support](https://supabase.com/dashboard/support/new) and we'll be happy to assist you. # Semantic search Learn how to search by meaning rather than exact keywords. Semantic search interprets the meaning behind user queries rather than exact [keywords](/docs/guides/ai/keyword-search). It uses machine learning to capture the intent and context behind the query, handling language nuances like synonyms, phrasing variations, and word relationships. ## When to use semantic search Semantic search is useful in applications where the depth of understanding and context is important for delivering relevant results. A good example is in customer support or knowledge base search engines. Users often phrase their problems or questions in various ways, and a traditional keyword-based search might not always retrieve the most helpful documents. With semantic search, the system can understand the meaning behind the queries and match them with relevant solutions or articles, even if the exact wording differs. For instance, a user searching for "increase text size on display" might miss articles titled "How to adjust font size in settings" in a keyword-based search system. However, a semantic search engine would understand the intent behind the query and correctly match it to relevant articles, regardless of the specific terminology used. It's also possible to combine semantic search with keyword search to get the best of both worlds. See [Hybrid search](/docs/guides/ai/hybrid-search) for more details. ## How semantic search works Semantic search uses an intermediate representation called an “embedding vector” to link database records with search queries. A vector, in the context of semantic search, is a list of numerical values. They represent various features of the text and allow for the semantic comparison between different pieces of text. The best way to think of embeddings is by plotting them on a graph, where each embedding is a single point whose coordinates are the numerical values within its vector. Importantly, embeddings are plotted such that similar concepts are positioned close together while dissimilar concepts are far apart. For more details, see [What are embeddings?](/docs/guides/ai/concepts#what-are-embeddings) Embeddings are generated using a language model, and embeddings are compared to each other using a similarity metric. The language model is trained to understand the semantics of language, including syntax, context, and the relationships between words. It generates embeddings for both the content in the database and the search queries. Then the similarity metric, often a function like cosine similarity or dot product, is used to compare the query embeddings with the document embeddings (in other words, to measure how close they are to each other on the graph). The documents with embeddings most similar to the query's are deemed the most relevant and are returned as search results. ## Embedding models There are many embedding models available today. Supabase Edge Functions has [built in support](/docs/guides/functions/examples/semantic-search) for the `gte-small` model. Others can be accessed through third-party APIs like [OpenAI](https://platform.openai.com/docs/guides/embeddings), where you send your text in the request and receive an embedding vector in the response. Others can run locally on your own compute, such as through Transformers.js for JavaScript implementations. For more information on local implementation, see [Generate embeddings](/docs/guides/ai/quickstarts/generate-text-embeddings). It's crucial to remember that when using embedding models with semantic search, you must use the same model for all embedding comparisons. Comparing embeddings created by different models will yield meaningless results. ## Semantic search in Postgres To implement semantic search in Postgres we use `pgvector` - an extension that allows for efficient storage and retrieval of high-dimensional vectors. These vectors are numerical representations of text (or other types of data) generated by embedding models. 1. Enable the `pgvector` extension by running: ```sql create extension vector with schema extensions; ``` 2. Create a table to store the embeddings: ```sql create table documents ( id bigint primary key generated always as identity, content text, embedding vector(512) ); ``` Or if you have an existing table, you can add a vector column like so: ```sql alter table documents add column embedding vector(512); ``` In this example, we create a column named `embedding` which uses the newly enabled `vector` data type. The size of the vector (as indicated in parentheses) represents the number of dimensions in the embedding. Here we use 512, but adjust this to match the number of dimensions produced by your embedding model. For more details on vector columns, including how to generate embeddings and store them, see [Vector columns](/docs/guides/ai/vector-columns). ### Similarity metric `pgvector` support 3 operators for computing distance between embeddings: | **Operator** | **Description** | | ------------ | ---------------------- | | `<->` | Euclidean distance | | `<#>` | negative inner product | | `<=>` | cosine distance | These operators are used directly in your SQL query to retrieve records that are most similar to the user's search query. Choosing the right operator depends on your needs. Inner product (also known as dot product) tends to be the fastest if your vectors are normalized. The easiest way to perform semantic search in Postgres is by creating a function: ```sql -- Match documents using cosine distance (<=>) create or replace function match_documents ( query_embedding vector(512), match_threshold float, match_count int ) returns setof documents language sql as $$ select * from documents where documents.embedding <=> query_embedding < 1 - match_threshold order by documents.embedding <=> query_embedding asc limit least(match_count, 200); $$; ``` Here we create a function `match_documents` that accepts three parameters: 1. `query_embedding`: a one-time embedding generated for the user's search query. Here we set the size to 512, but adjust this to match the number of dimensions produced by your embedding model. 2. `match_threshold`: the minimum similarity between embeddings. This is a value between 1 and -1, where 1 is most similar and -1 is most dissimilar. 3. `match_count`: the maximum number of results to return. Note the query may return less than this number if `match_threshold` resulted in a small shortlist. Limited to 200 records to avoid unintentionally overloading your database. In this example, we return a `setof documents` and refer to `documents` throughout the query. Adjust this to use the relevant tables in your application. You'll notice we are using the cosine distance (`<=>`) operator in our query. Cosine distance is a safe default when you don't know whether or not your embeddings are normalized. If you know for a fact that they are normalized (for example, your embedding is returned from OpenAI), you can use negative inner product (`<#>`) for better performance: ```sql -- Match documents using negative inner product (<#>) create or replace function match_documents ( query_embedding vector(512), match_threshold float, match_count int ) returns setof documents language sql as $$ select * from documents where documents.embedding <#> query_embedding < -match_threshold order by documents.embedding <#> query_embedding asc limit least(match_count, 200); $$; ``` Note that since `<#>` is negative, we negate `match_threshold` accordingly in the `where` clause. For more information on the different operators, see the [pgvector docs](https://github.com/pgvector/pgvector?tab=readme-ov-file#vector-operators). ### Calling from your application Finally you can execute this function from your application. If you are using a Supabase client library such as [`supabase-js`](https://github.com/supabase/supabase-js), you can invoke it using the `rpc()` method: ```tsx const { data: documents } = await supabase.rpc('match_documents', { query_embedding: embedding, // pass the query embedding match_threshold: 0.78, // choose an appropriate threshold for your data match_count: 10, // choose the number of matches }) ``` You can also call this method directly from SQL: ```sql select * from match_documents( '[...]'::vector(512), -- pass the query embedding 0.78, -- chose an appropriate threshold for your data 10 -- choose the number of matches ); ``` In this scenario, you'll likely use a Postgres client library to establish a direct connection from your application to the database. It's best practice to parameterize your arguments before executing the query. ## Next steps As your database scales, you will need an index on your vector columns to maintain fast query speeds. See [Vector indexes](/docs/guides/ai/vector-indexes) for an in-depth guide on the different types of indexes and how they work. ## See also * [Embedding concepts](/docs/guides/ai/concepts) * [Vector columns](/docs/guides/ai/vector-columns) * [Vector indexes](/docs/guides/ai/vector-indexes) * [Hybrid search](/docs/guides/ai/hybrid-search) * [Keyword search](/docs/guides/ai/keyword-search) # Structured and Unstructured Supabase is flexible enough to associate structured and unstructured metadata with embeddings. Most vector stores treat metadata associated with embeddings like NoSQL, unstructured data. Supabase is flexible enough to store unstructured and structured metadata. ## Structured ```sql create table docs ( id uuid primary key, embedding vector(3), content text, url text ); insert into docs (id, embedding, content, url) values ('79409372-7556-4ccc-ab8f-5786a6cfa4f7', array[0.1, 0.2, 0.3], 'Hello world', '/hello-world'); ``` Notice that we've associated two pieces of metadata, `content` and `url`, with the embedding. Those fields can be filtered, constrained, indexed, and generally operated on using the full power of SQL. Structured metadata fits naturally with a traditional Supabase application, and can be managed via database [migrations](/docs/guides/deployment/database-migrations). ## Unstructured ```sql create table docs ( id uuid primary key, embedding vector(3), meta jsonb ); insert into docs (id, embedding, meta) values ( '79409372-7556-4ccc-ab8f-5786a6cfa4f7', array[0.1, 0.2, 0.3], '{"content": "Hello world", "url": "/hello-world"}' ); ``` An unstructured approach does not specify the metadata fields that are expected. It stores all metadata in a flexible `json`/`jsonb` column. The tradeoff is that the querying/filtering capabilities of a schemaless data type are less flexible than when each field has a dedicated column. It also pushes the burden of metadata data integrity onto application code, which is more error prone than enforcing constraints in the database. The unstructured approach is recommended: * for ephemeral/interactive workloads e.g. data science or scientific research * when metadata fields are user-defined or unknown * during rapid prototyping Client libraries like python's [vecs](https://github.com/supabase/vecs) use this structure. For example, running: ```py #!/usr/bin/env python3 import vecs # In practice, do not hard-code your password. Use environment variables. DB_CONNECTION = "postgresql://:@:/" # create vector store client vx = vecs.create_client(DB_CONNECTION) docs = vx.get_or_create_collection(name="docs", dimension=1536) docs.upsert(vectors=[ ('79409372-7556-4ccc-ab8f-5786a6cfa4f7', [100, 200, 300], { url: '/hello-world' }) ]) ``` automatically creates the unstructured SQL table during the call to `get_or_create_collection`. Note that when working with client libraries that emit SQL DDL, like `create table ...`, you should add that SQL to your migrations when moving to production to maintain a single source of truth for your database's schema. ## Hybrid The structured metadata style is recommended when the fields being tracked are known in advance. If you have a combination of known and unknown metadata fields, you can accommodate the unknown fields by adding a `json`/`jsonb` column to the table. In that situation, known fields should continue to use dedicated columns for best query performance and throughput. ```sql create table docs ( id uuid primary key, embedding vector(3), content text, url string, meta jsonb ); insert into docs (id, embedding, content, url, meta) values ( '79409372-7556-4ccc-ab8f-5786a6cfa4f7', array[0.1, 0.2, 0.3], 'Hello world', '/hello-world', '{"key": "value"}' ); ``` ## Choosing the right model Both approaches create a table where you can store your embeddings and some metadata. You should choose the best approach for your use-case. In summary: * Structured metadata is best when fields are known in advance or query patterns are predictable e.g. a production Supabase application * Unstructured metadata is best when fields are unknown/user-defined or when working with data interactively e.g. exploratory research Both approaches are valid, and the one you should choose depends on your use-case. # Python client Manage unstructured vector stores in PostgreSQL. Supabase provides a Python client called [`vecs`](https://github.com/supabase/vecs) for managing unstructured vector stores. This client provides a set of useful tools for creating and querying collections in Postgres using the [pgvector](/docs/guides/database/extensions/pgvector) extension. ## Quick start Let's see how Vecs works using a local database. Make sure you have the Supabase CLI [installed](/docs/guides/cli#installation) on your machine. ### Initialize your project Start a local Postgres instance in any folder using the `init` and `start` commands. Make sure you have Docker running! ```bash # Initialize your project supabase init # Start Postgres supabase start ``` ### Create a collection Inside a Python shell, run the following commands to create a new collection called "docs", with 3 dimensions. ```py import vecs # create vector store client vx = vecs.create_client("postgresql://postgres:postgres@localhost:54322/postgres") # create a collection of vectors with 3 dimensions docs = vx.get_or_create_collection(name="docs", dimension=3) ``` ### Add embeddings Now we can insert some embeddings into our "docs" collection using the `upsert()` command: ```py import vecs # create vector store client docs = vecs.get_or_create_collection(name="docs", dimension=3) # a collection of vectors with 3 dimensions vectors=[ ("vec0", [0.1, 0.2, 0.3], {"year": 1973}), ("vec1", [0.7, 0.8, 0.9], {"year": 2012}) ] # insert our vectors docs.upsert(vectors=vectors) ``` ### Query the collection You can now query the collection to retrieve a relevant match: ```py import vecs docs = vecs.get_or_create_collection(name="docs", dimension=3) # query the collection filtering metadata for "year" = 2012 docs.query( data=[0.4,0.5,0.6], # required limit=1, # number of records to return filters={"year": {"$eq": 2012}}, # metadata filters ) ``` ## Deep dive For a more in-depth guide on `vecs` collections, see [API](/docs/guides/ai/python/api). ## Resources * Official Vecs Documentation: https://supabase.github.io/vecs/api * Source Code: https://github.com/supabase/vecs # Vector columns Supabase offers a number of different ways to store and query vectors within Postgres. The SQL included in this guide is applicable for clients in all programming languages. If you are a Python user see your [Python client options](/docs/guides/ai/python-clients) after reading the `Learn` section. Vectors in Supabase are enabled via [pgvector](https://github.com/pgvector/pgvector/), a Postgres extension for storing and querying vectors in Postgres. It can be used to store [embeddings](/docs/guides/ai/concepts#what-are-embeddings). ## Usage ### Enable the extension ### Create a table to store vectors After enabling the `vector` extension, you will get access to a new data type called `vector`. The size of the vector (indicated in parenthesis) represents the number of dimensions stored in that vector. ```sql create table documents ( id serial primary key, title text not null, body text not null, embedding vector(384) ); ``` In the above SQL snippet, we create a `documents` table with a column called `embedding` (note this is just a regular Postgres column - you can name it whatever you like). We give the `embedding` column a `vector` data type with 384 dimensions. Change this to the number of dimensions produced by your embedding model. For example, if you are [generating embeddings](/docs/guides/ai/quickstarts/generate-text-embeddings) using the open source [`gte-small`](https://huggingface.co/Supabase/gte-small) model, you would set this number to 384 since that model produces 384 dimensions. ### Storing a vector / embedding In this example we'll generate a vector using Transformers.js, then store it in the database using the Supabase JavaScript client. ```js import { pipeline } from '@xenova/transformers' const generateEmbedding = await pipeline('feature-extraction', 'Supabase/gte-small') const title = 'First post!' const body = 'Hello world!' // Generate a vector using Transformers.js const output = await generateEmbedding(body, { pooling: 'mean', normalize: true, }) // Extract the embedding output const embedding = Array.from(output.data) // Store the vector in Postgres const { data, error } = await supabase.from('documents').insert({ title, body, embedding, }) ``` This example uses the JavaScript Supabase client, but you can modify it to work with any [supported language library](/docs#client-libraries). ### Querying a vector / embedding Similarity search is the most common use case for vectors. `pgvector` support 3 new operators for computing distance: | Operator | Description | | -------- | ---------------------- | | `<->` | Euclidean distance | | `<#>` | negative inner product | | `<=>` | cosine distance | Choosing the right operator depends on your needs. Dot product tends to be the fastest if your vectors are normalized. For more information on how embeddings work and how they relate to each other, see [What are Embeddings?](/docs/guides/ai/concepts#what-are-embeddings). Supabase client libraries like `supabase-js` connect to your Postgres instance via [PostgREST](/docs/guides/getting-started/architecture#postgrest-api). PostgREST does not currently support `pgvector` similarity operators, so we'll need to wrap our query in a Postgres function and call it via the `rpc()` method: ```sql create or replace function match_documents ( query_embedding vector(384), match_threshold float, match_count int ) returns table ( id bigint, title text, body text, similarity float ) language sql stable as $$ select documents.id, documents.title, documents.body, 1 - (documents.embedding <=> query_embedding) as similarity from documents where 1 - (documents.embedding <=> query_embedding) > match_threshold order by (documents.embedding <=> query_embedding) asc limit match_count; $$; ``` This function takes a `query_embedding` argument and compares it to all other embeddings in the `documents` table. Each comparison returns a similarity score. If the similarity is greater than the `match_threshold` argument, it is returned. The number of rows returned is limited by the `match_count` argument. Feel free to modify this method to fit the needs of your application. The `match_threshold` ensures that only documents that have a minimum similarity to the `query_embedding` are returned. Without this, you may end up returning documents that subjectively don't match. This value will vary for each application - you will need to perform your own testing to determine the threshold that makes sense for your app. If you index your vector column, ensure that the `order by` sorts by the distance function directly (rather than sorting by the calculated `similarity` column, which may lead to the index being ignored and poor performance). To execute the function from your client library, call `rpc()` with the name of your Postgres function: ```ts const { data: documents } = await supabaseClient.rpc('match_documents', { query_embedding: embedding, // Pass the embedding you want to compare match_threshold: 0.78, // Choose an appropriate threshold for your data match_count: 10, // Choose the number of matches }) ``` In this example `embedding` would be another embedding you wish to compare against your table of pre-generated embedding documents. For example if you were building a search engine, every time the user submits their query you would first generate an embedding on the search query itself, then pass it into the above `rpc()` function to match. Vectors and embeddings can be used for much more than search. Learn more about embeddings at [What are Embeddings?](/docs/guides/ai/concepts#what-are-embeddings). ### Indexes Once your vector table starts to grow, you will likely want to add an index to speed up queries. See [Vector indexes](/docs/guides/ai/vector-indexes) to learn how vector indexes work and how to create them. # Vector indexes Once your vector table starts to grow, you will likely want to add an index to speed up queries. Without indexes, you'll be performing a sequential scan which can be a resource-intensive operation when you have many records. ## Choosing an index Today `pgvector` supports two types of indexes: * [HNSW](/docs/guides/ai/vector-indexes/hnsw-indexes) * [IVFFlat](/docs/guides/ai/vector-indexes/ivf-indexes) In general we recommend using [HNSW](/docs/guides/ai/vector-indexes/hnsw-indexes) because of its [performance](https://supabase.com/blog/increase-performance-pgvector-hnsw#hnsw-performance-1536-dimensions) and [robustness against changing data](/docs/guides/ai/vector-indexes/hnsw-indexes#when-should-you-create-hnsw-indexes). ## Distance operators Indexes can be used to improve performance of nearest neighbor search using various distance measures. `pgvector` includes 3 distance operators: | Operator | Description | [**Operator class**](https://www.postgresql.org/docs/current/sql-createopclass.html) | | -------- | ---------------------- | ------------------------------------------------------------------------------------ | | `<->` | Euclidean distance | `vector_l2_ops` | | `<#>` | negative inner product | `vector_ip_ops` | | `<=>` | cosine distance | `vector_cosine_ops` | Currently vectors with up to 2,000 dimensions can be indexed. ## Resources Read more about indexing on `pgvector`'s [GitHub page](https://github.com/pgvector/pgvector#indexing). # HNSW indexes HNSW is an algorithm for approximate nearest neighbor search. It is a frequently used index type that can improve performance when querying highly-dimensional vectors, like those representing embeddings. ## Usage The way you create an HNSW index depends on the distance operator you are using. `pgvector` includes 3 distance operators: | Operator | Description | [**Operator class**](https://www.postgresql.org/docs/current/sql-createopclass.html) | | -------- | ---------------------- | ------------------------------------------------------------------------------------ | | `<->` | Euclidean distance | `vector_l2_ops` | | `<#>` | negative inner product | `vector_ip_ops` | | `<=>` | cosine distance | `vector_cosine_ops` | Use the following SQL commands to create an HNSW index for the operator(s) used in your queries. ### Euclidean L2 distance (`vector_l2_ops`) ```sql create index on items using hnsw (column_name vector_l2_ops); ``` ### Inner product (`vector_ip_ops`) ```sql create index on items using hnsw (column_name vector_ip_ops); ``` ### Cosine distance (`vector_cosine_ops`) ```sql create index on items using hnsw (column_name vector_cosine_ops); ``` Currently vectors with up to 2,000 dimensions can be indexed. ## How does HNSW work? HNSW uses proximity graphs (graphs connecting nodes based on distance between them) to approximate nearest-neighbor search. To understand HNSW, we can break it down into 2 parts: * **Hierarchical (H):** The algorithm operates over multiple layers * **Navigable Small World (NSW):** Each vector is a node within a graph and is connected to several other nodes ### Hierarchical The hierarchical aspect of HNSW builds off of the idea of skip lists. Skip lists are multi-layer linked lists. The bottom layer is a regular linked list connecting an ordered sequence of elements. Each new layer above removes some elements from the underlying layer (based on a fixed probability), producing a sparser subsequence that “skips” over elements. When searching for an element, the algorithm begins at the top layer and traverses its linked list horizontally. If the target element is found, the algorithm stops and returns it. Otherwise if the next element in the list is greater than the target (or `NULL`), the algorithm drops down to the next layer below. Since each layer below is less sparse than the layer above (with the bottom layer connecting all elements), the target will eventually be found. Skip lists offer O(log n) average complexity for both search and insertion/deletion. ### Navigable Small World A navigable small world (NSW) is a special type of proximity graph that also includes long-range connections between nodes. These long-range connections support the “small world” property of the graph, meaning almost every node can be reached from any other node within a few hops. Without these additional long-range connections, many hops would be required to reach a far-away node. The “navigable” part of NSW specifically refers to the ability to logarithmically scale the greedy search algorithm on the graph, an algorithm that attempts to make only the locally optimal choice at each hop. Without this property, the graph may still be considered a small world with short paths between far-away nodes, but the greedy algorithm tends to miss them. Greedy search is ideal for NSW because it is quick to navigate and has low computational costs. ### **Hierarchical +** Navigable Small World HNSW combines these two concepts. From the hierarchical perspective, the bottom layer consists of a NSW made up of short links between nodes. Each layer above “skips” elements and creates longer links between nodes further away from each other. Just like skip lists, search starts at the top layer and works its way down until it finds the target element. However, instead of comparing a scalar value at each layer to determine whether or not to descend to the layer below, a multi-dimensional distance measure (such as Euclidean distance) is used. ## When should you create HNSW indexes? HNSW should be your default choice when creating a vector index. Add the index when you don't need 100% accuracy and are willing to trade a small amount of accuracy for a lot of throughput. Unlike IVFFlat indexes, you are safe to build an HNSW index immediately after the table is created. HNSW indexes are based on graphs which inherently are not affected by the same limitations as IVFFlat. As new data is added to the table, the index will be filled automatically and the index structure will remain optimal. ## Resources Read more about indexing on `pgvector`'s [GitHub page](https://github.com/pgvector/pgvector#indexing). # IVFFlat indexes IVFFlat is a type of vector index for approximate nearest neighbor search. It is a frequently used index type that can improve performance when querying highly-dimensional vectors, like those representing embeddings. ## Choosing an index Today `pgvector` supports two types of indexes: * [HNSW](/docs/guides/ai/vector-indexes/hnsw-indexes) * [IVFFlat](/docs/guides/ai/vector-indexes/ivf-indexes) In general we recommend using [HNSW](/docs/guides/ai/vector-indexes/hnsw-indexes) because of its [performance](https://supabase.com/blog/increase-performance-pgvector-hnsw#hnsw-performance-1536-dimensions) and [robustness against changing data](/docs/guides/ai/vector-indexes/hnsw-indexes#when-should-you-create-hnsw-indexes). If you have a special use case that requires IVFFlat instead, keep reading. ## Usage The way you create an IVFFlat index depends on the distance operator you are using. `pgvector` includes 3 distance operators: | Operator | Description | [**Operator class**](https://www.postgresql.org/docs/current/sql-createopclass.html) | | -------- | ---------------------- | ------------------------------------------------------------------------------------ | | `<->` | Euclidean distance | `vector_l2_ops` | | `<#>` | negative inner product | `vector_ip_ops` | | `<=>` | cosine distance | `vector_cosine_ops` | Use the following SQL commands to create an IVFFlat index for the operator(s) used in your queries. ### Euclidean L2 distance (`vector_l2_ops`) ```sql create index on items using ivfflat (column_name vector_l2_ops) with (lists = 100); ``` ### Inner product (`vector_ip_ops`) ```sql create index on items using ivfflat (column_name vector_ip_ops) with (lists = 100); ``` ### Cosine distance (`vector_cosine_ops`) ```sql create index on items using ivfflat (column_name vector_cosine_ops) with (lists = 100); ``` Currently vectors with up to 2,000 dimensions can be indexed. ## How does IVFFlat work? IVF stands for 'inverted file indexes'. It works by clustering your vectors in order to reduce the similarity search scope. Rather than comparing a vector to every other vector, the vector is only compared against vectors within the same cell cluster (or nearby clusters, depending on your configuration). ### Inverted lists (cell clusters) When you create the index, you choose the number of inverted lists (cell clusters). Increase this number to speed up queries, but at the expense of recall. For example, to create an index with 100 lists on a column that uses the cosine operator: ```sql create index on items using ivfflat (column_name vector_cosine_ops) with (lists = 100); ``` For more info on the different operators, see [Distance operations](#distance-operators). For every query, you can set the number of probes (1 by default). The number of probes corresponds to the number of nearby cells to probe for a match. Increase this for better recall at the expense of speed. To set the number of probes for the duration of the session run: ```sql set ivfflat.probes = 10; ``` To set the number of probes only for the current transaction run: ```sql begin; set local ivfflat.probes = 10; select ... commit; ``` If the number of probes is the same as the number of lists, exact nearest neighbor search will be performed and the planner won't use the index. ### Approximate nearest neighbor One important note with IVF indexes is that nearest neighbor search is approximate, since exact search on high dimensional data can't be indexed efficiently. This means that similarity results will change (slightly) after you add an index (trading recall for speed). ## When should you create IVFFlat indexes? `pgvector` recommends building IVFFlat indexes only after the table has sufficient data, so that the internal IVFFlat cell clusters are based on your data's distribution. Anytime the distribution changes significantly, consider rebuilding indexes. ## Resources Read more about indexing on `pgvector`'s [GitHub page](https://github.com/pgvector/pgvector#indexing). # REST API Supabase auto-generates an API directly from your database schema allowing you to connect to your database through a restful interface, directly from the browser. The API is auto-generated from your database and is designed to get you building as fast as possible, without writing a single line of code. You can use them directly from the browser (two-tier architecture), or as a complement to your own API server (three-tier architecture). ## Features \[#rest-api-overview] Supabase provides a RESTful API using [PostgREST](https://postgrest.org/). This is a very thin API layer on top of Postgres. It exposes everything you need from a CRUD API at the URL `https://.supabase.co/rest/v1/`. The REST interface is automatically reflected from your database's schema and is: * **Instant and auto-generated.** As you update your database the changes are immediately accessible through your API. * **Self documenting.** Supabase generates documentation in the Dashboard which updates as you make database changes. * **Secure.** The API is configured to work with PostgreSQL's Row Level Security, provisioned behind an API gateway with key-auth enabled. * **Fast.** Our benchmarks for basic reads are more than 300% faster than Firebase. The API is a very thin layer on top of Postgres, which does most of the heavy lifting. * **Scalable.** The API can serve thousands of simultaneous requests, and works well for Serverless workloads. The reflected API is designed to retain as much of Postgres' capability as possible including: * Basic CRUD operations (Create/Read/Update/Delete) * Arbitrarily deep relationships among tables/views, functions that return table types can also nest related tables/views. * Works with Postgres Views, Materialized Views and Foreign Tables * Works with Postgres Functions * User defined computed columns and computed relationships * The Postgres security model - including Row Level Security, Roles, and Grants. The REST API resolves all requests to a single SQL statement leading to fast response times and high throughput. Reference: * [Docs](https://postgrest.org/) * [Source Code](https://github.com/PostgREST/postgrest) ## API URL and keys You can find the API URL and Keys in the [Dashboard](https://supabase.com/dashboard/project/_/settings/api). # Understanding API Keys Supabase provides two default keys when you create a project: an `anon` key, and a `service_role` key. You can find both keys in the [API Settings](https://supabase.com/dashboard/project/_/settings/api). The data APIs are designed to work with Postgres Row Level Security (RLS). These keys both map to Postgres roles. You can find an `anon` user and a `service_role` user in the [Roles](http://supabase.com/dashboard/project/_/database/roles) section of the dashboard. The keys are both long-lived JWTs. If you decode these keys, you will see that they contain the "role", an "issued date", and an "expiry date" ~10 years in the future. ```json { "role": "anon", "iat": 1625137684, "exp": 1940713684 } ``` ## The `anon` key The `anon` key has very few privileges. You can use it in your [RLS policies](/docs/guides/database/postgres/row-level-security) to allow unauthenticated access. For example, this policy will allow unauthenticated access to the `profiles` table: ```sql create policy "Allow public access" on profiles to anon for select using (true); ``` And similarly for disallowing access: ```sql create policy "Disallow public access" on profiles to anon for select using (false); ``` If you are using [Supabase Auth](/docs/guides/auth/overview), then the `anon` role will automatically update to `authenticated` once a user is logged in: ```sql create policy "Allow access to authenticated users" on profiles to authenticated for select using (true); ``` ## The `service_role` key The "service\_role" is a predefined Postgres role with elevated privileges, designed to perform various administrative and service-related tasks. It can bypass Row Level Security, so it should only be used on a private server. A common use case for the `service_role` key is running data analytics jobs on the backend. To support joins on user id, it is often useful to grant the service role read access to `auth.users` table. ```sql grant select on table auth.users to service_role; ``` We have [partnered with GitHub](https://github.blog/changelog/2022-03-28-supabase-is-now-a-github-secret-scanning-partner/) to scan for Supabase `service_role` keys pushed to public repositories. If they detect any keys with service\_role privileges being pushed to GitHub, they will forward the API key to us, so that we can automatically revoke the detected secrets and notify you, protecting your data against malicious actors. # How to do automatic retries with `supabase-js` Learn how to add automatic retries to your Supabase API requests using `fetch-retry`. The `fetch-retry` package allows you to add retry logic to `fetch` requests, making it a useful tool for enhancing the resilience of API calls in your Supabase applications. Here's a step-by-step guide on how to integrate `fetch-retry` with the `supabase-js` library. ## 1. Install dependencies To get started, ensure you have both `supabase-js` and `fetch-retry` installed in your project: ```bash npm install @supabase/supabase-js fetch-retry ``` ## 2. Wrap the fetch function The `fetch-retry` package works by wrapping the native `fetch` function. You can create a custom fetch instance with retry logic and pass it to the `supabase-js` client. ```javascript import { createClient } from '@supabase/supabase-js' import fetchRetry from 'fetch-retry' // Wrap the global fetch with fetch-retry const fetchWithRetry = fetchRetry(fetch) // Create a Supabase client instance with the custom fetch const supabase = createClient('https://your-supabase-url.supabase.co', 'your-anon-key', { global: { fetch: fetchWithRetry, }, }) ``` ## 3. Configure retry options You can configure `fetch-retry` options to control retry behavior, such as the number of retries, retry delay, and which errors should trigger a retry. Here is an example with custom retry options: ```javascript const fetchWithRetry = fetchRetry(fetch, { retries: 3, // Number of retry attempts retryDelay: (attempt) => Math.min(1000 * 2 ** attempt, 30000), // Exponential backoff retryOn: [520], // Retry only on Cloudflare errors }) ``` In this example, the `retryDelay` function implements an exponential backoff strategy, and retries are triggered only for specific HTTP status codes. ## 4. Using the Supabase client With `fetch-retry` integrated, you can use the Supabase client as usual. The retry logic will automatically apply to all network requests made by `supabase-js`. ```javascript async function fetchData() { const { data, error } = await supabase.from('your_table').select('*') if (error) { console.error('Error fetching data:', error) } else { console.log('Fetched data:', data) } } fetchData() ``` ## 5. Fine-Tuning retries for specific requests If you need different retry logic for certain requests, you can use the `retryOn` with a custom function to inspect the URL or response and decide whether to retry the request. ```javascript const fetchWithRetry = fetchRetry(fetch, { retryDelay: (attempt) => Math.min(1000 * 2 ** attempt, 30000), retryOn: (attempt, error, response) => { const shouldRetry = (attempt: number, error: Error | null, response: Response | null) => attempt < 3 && response && response.status == 520 // Cloudflare errors && response.url.includes('rpc/your_stored_procedure') if (shouldRetry(attempt, error, response)) { console.log(`Retrying request... Attempt #${attempt}`, response) return true } return false } }) async function yourStoredProcedure() { const { data, error } = await supabase .rpc('your_stored_procedure', { param1: 'value1' }); if (error) { console.log('Error executing RPC:', error); } else { console.log('Response:', data); } } yourStoredProcedure(); ``` By using `retryOn` with a custom function, you can define specific conditions for retrying requests. In this example, the retry logic is applied only to requests targeting a specific stored procedure. ## Conclusion Integrating `fetch-retry` with `supabase-js` is a straightforward way to add robustness to your Supabase API requests. By handling transient errors and implementing retry strategies, you can improve the reliability of your application while maintaining a seamless user experience. # Creating API Routes API routes are automatically created when you create Postgres Tables, Views, or Functions. ## Create a table Let's create our first API route by creating a table called `todos` to store tasks. This creates a corresponding route `todos` which can accept `GET`, `POST`, `PATCH`, & `DELETE` requests. ## API URL and keys Every Supabase project has a unique API URL. Your API is secured behind an API gateway which requires an API Key for every request. 1. Go to the [Settings](https://supabase.com/dashboard/project/_/settings/general) page in the Dashboard. 2. Click **API** in the sidebar. 3. Find your API `URL`, `anon`, and `service_role` keys on this page. The REST API is accessible through the URL `https://.supabase.co/rest/v1` Both of these routes require the `anon` key to be passed through an `apikey` header. ## Using the API You can interact with your API directly via HTTP requests, or you can use the client libraries which we provide. Let's see how to make a request to the `todos` table which we created in the first step, using the API URL (`SUPABASE_URL`) and Key (`SUPABASE_ANON_KEY`) we provided: JS Reference: [`select()`](/docs/reference/javascript/select), [`insert()`](/docs/reference/javascript/insert), [`update()`](/docs/reference/javascript/update), [`upsert()`](/docs/reference/javascript/upsert), [`delete()`](/docs/reference/javascript/delete), [`rpc()`](/docs/reference/javascript/rpc) (call Postgres functions). # Build an API route in less than 2 minutes. Create your first API route by creating a table called `todos` to store tasks. Let's create our first REST route which we can query using `cURL` or the browser. We'll create a database table called `todos` for storing tasks. This creates a corresponding API route `/rest/v1/todos` which can accept `GET`, `POST`, `PATCH`, & `DELETE` requests. ## Bonus There are several options for accessing your data: ### Browser You can query the route in your browser, by appending the `anon` key as a query parameter: `https://.supabase.co/rest/v1/todos?apikey=` ### Client libraries We provide a number of [Client Libraries](https://github.com/supabase/supabase#client-libraries). # Auto-generated documentation Supabase generates documentation in the [Dashboard](https://supabase.com/dashboard) which updates as you make database changes. 1. Go to the [API](https://supabase.com/dashboard/project/_/api) page in the Dashboard. 2. Select any table under **Tables and Views** in the sidebar. 3. Switch between the JavaScript and the cURL docs using the tabs. # Client Libraries Supabase provides client libraries for the REST and Realtime APIs. Some libraries are officially supported, and some are contributed by the community. ## Official libraries | `Language` | `Source Code` | `Documentation` | | --------------------- | ---------------------------------------------------------------------------------------------------- | ------------------------------------------------------------------- | | Javascript/Typescript | [supabase-js](https://github.com/supabase/supabase-js) | [Docs](https://supabase.com/docs/reference/javascript/introduction) | | Dart/Flutter | [supabase-flutter](https://github.com/supabase/supabase-flutter/tree/main/packages/supabase_flutter) | [Docs](https://supabase.com/docs/reference/dart/introduction) | | Swift | [supabase-swift](https://github.com/supabase/supabase-swift) | [Docs](https://supabase.com/docs/reference/swift/introduction) | | Python | [supabase-py](https://github.com/supabase/supabase-py) | [Docs](https://supabase.com/docs/reference/python/initializing) | ## Community libraries | `Language` | `Source Code` | `Documentation` | | ----------------------- | -------------------------------------------------------------------------------- | --------------------------------------------------------------- | | C# | [supabase-csharp](https://github.com/supabase-community/supabase-csharp) | [Docs](https://supabase.com/docs/reference/csharp/introduction) | | Go | [supabase-go](https://github.com/supabase-community/supabase-go) | | | Kotlin | [supabase-kt](https://github.com/supabase-community/supabase-kt) | [Docs](https://supabase.com/docs/reference/kotlin/introduction) | | Ruby | [supabase-rb](https://github.com/supabase-community/supabase-rb) | | | Godot Engine (GDScript) | [supabase-gdscript](https://github.com/supabase-community/godot-engine.supabase) | | # Generating TypeScript Types How to generate types for your API and Supabase libraries. Supabase APIs are generated from your database, which means that we can use database introspection to generate type-safe API definitions. ## Generating types from project dashboard Supabase allows you to generate and download TypeScript types directly from the [project dashboard](https://supabase.com/dashboard/project/_/api?page=tables-intro). ## Generating types using Supabase CLI The Supabase CLI is a single binary Go application that provides everything you need to setup a local development environment. You can [install the CLI](https://www.npmjs.com/package/supabase) via npm or other supported package managers. The minimum required version of the CLI is [v1.8.1](https://github.com/supabase/cli/releases). ```bash npm i supabase@">=1.8.1" --save-dev ``` Login with your Personal Access Token: ```bash npx supabase login ``` Before generating types, ensure you initialize your Supabase project: ```bash npx supabase init ``` Generate types for your project to produce the `database.types.ts` file: ```bash npx supabase gen types typescript --project-id "$PROJECT_REF" --schema public > database.types.ts ``` or in case of local development: ```bash npx supabase gen types typescript --local > database.types.ts ``` These types are generated from your database schema. Given a table `public.movies`, the generated types will look like: ```sql create table public.movies ( id bigint generated always as identity primary key, name text not null, data jsonb null ); ``` ```ts ./database.types.ts export type Json = string | number | boolean | null | { [key: string]: Json | undefined } | Json[] export interface Database { public: { Tables: { movies: { Row: { // the data expected from .select() id: number name: string data: Json | null } Insert: { // the data to be passed to .insert() id?: never // generated columns must not be supplied name: string // `not null` columns with no default must be supplied data?: Json | null // nullable columns can be omitted } Update: { // the data to be passed to .update() id?: never name?: string // `not null` columns are optional on .update() data?: Json | null } } } } } ``` ## Using TypeScript type definitions You can supply the type definitions to `supabase-js` like so: ```ts ./index.tsx import { createClient } from '@supabase/supabase-js' import { Database } from './database.types' const supabase = createClient(process.env.SUPABASE_URL, process.env.SUPABASE_ANON_KEY) ``` ## Helper types for tables and joins You can use the following helper types to make the generated TypeScript types easier to use. Sometimes the generated types are not what you expect. For example, a view's column may show up as nullable when you expect it to be `not null`. Using [type-fest](https://github.com/sindresorhus/type-fest), you can override the types like so: ```ts ./database-generated.types.ts export type Json = // ... export interface Database { // ... } ``` ```ts ./database.types.ts import { MergeDeep } from 'type-fest' import { Database as DatabaseGenerated } from './database-generated.types' export { Json } from './database-generated.types' // Override the type for a specific column in a view: export type Database = MergeDeep< DatabaseGenerated, { public: { Views: { movies_view: { Row: { // id is a primary key in public.movies, so it must be `not null` id: number } } } } } > ``` You can also override the type of an individual successful response if needed: ```ts // Partial type override allows you to only override some of the properties in your results const { data } = await supabase.from('countries').select().overrideTypes>() // For a full replacement of the original return type use the `{ merge: false }` property as second argument const { data } = await supabase .from('countries') .select() .overrideTypes, { merge: false }>() // Use it with `maybeSingle` or `single` const { data } = await supabase.from('countries').select().single().overrideTypes<{ id: string }>() ``` ### Type shorthands The generated types provide shorthands for accessing tables and enums. ```ts ./index.ts import { Database, Tables, Enums } from "./database.types.ts"; // Before 😕 let movie: Database['public']['Tables']['movies']['Row'] = // ... // After 😍 let movie: Tables<'movies'> ``` ### Response types for complex queries `supabase-js` always returns a `data` object (for success), and an `error` object (for unsuccessful requests). These helper types provide the result types from any query, including nested types for database joins. Given the following schema with a relation between cities and countries: ```sql create table countries ( "id" serial primary key, "name" text ); create table cities ( "id" serial primary key, "name" text, "country_id" int references "countries" ); ``` We can get the nested `CountriesWithCities` type like this: ```ts import { QueryResult, QueryData, QueryError } from '@supabase/supabase-js' const countriesWithCitiesQuery = supabase.from('countries').select(` id, name, cities ( id, name ) `) type CountriesWithCities = QueryData const { data, error } = await countriesWithCitiesQuery if (error) throw error const countriesWithCities: CountriesWithCities = data ``` ## Update types automatically with GitHub Actions One way to keep your type definitions in sync with your database is to set up a GitHub action that runs on a schedule. Add the following script to your `package.json` to run it using `npm run update-types` ```json "update-types": "npx supabase gen types --lang=typescript --project-id \"$PROJECT_REF\" > database.types.ts" ``` Create a file `.github/workflows/update-types.yml` with the following snippet to define the action along with the environment variables. This script will commit new type changes to your repo every night. ```yaml name: Update database types on: schedule: # sets the action to run daily. You can modify this to run the action more or less frequently - cron: '0 0 * * *' jobs: update: runs-on: ubuntu-latest permissions: contents: write env: SUPABASE_ACCESS_TOKEN: ${{ secrets.ACCESS_TOKEN }} PROJECT_REF: steps: - uses: actions/checkout@v4 with: persist-credentials: false fetch-depth: 0 - uses: actions/setup-node@v4 with: node-version: 22 - run: npm run update-types - name: check for file changes id: git_status run: | echo "status=$(git status -s)" >> $GITHUB_OUTPUT - name: Commit files if: ${{contains(steps.git_status.outputs.status, ' ')}} run: | git add database.types.ts git config --local user.email "41898282+github-actions[bot]@users.noreply.github.com" git config --local user.name "github-actions[bot]" git commit -m "Update database types" -a - name: Push changes if: ${{contains(steps.git_status.outputs.status, ' ')}} uses: ad-m/github-push-action@master with: github_token: ${{ secrets.GITHUB_TOKEN }} branch: ${{ github.ref }} ``` Alternatively, you can use a community-supported GitHub action: [`generate-supabase-db-types-github-action`](https://github.com/lyqht/generate-supabase-db-types-github-action). ## Resources * [Generating Supabase types with GitHub Actions](https://blog.esteetey.dev/how-to-create-and-test-a-github-action-that-generates-types-from-supabase-database) # Securing your API The data APIs are designed to work with Postgres Row Level Security (RLS). If you use [Supabase Auth](/docs/guides/auth), you can restrict data based on the logged-in user. To control access to your data, you can use [Policies](/docs/guides/auth#policies). ## Enabling row level security Any table you create in the `public` schema will be accessible via the Supabase Data API. To restrict access, enable Row Level Security (RLS) on all tables, views, and functions in the `public` schema. You can then write RLS policies to grant users access to specific database rows or functions based on their authentication token. Any table created through the Supabase Dashboard will have RLS enabled by default. If you created the tables via the SQL editor or via another way, enable RLS like so: With RLS enabled, you can create Policies that allow or disallow users to access and update data. We provide a detailed guide for creating Row Level Security Policies in our [Authorization documentation](/docs/guides/database/postgres/row-level-security). ## Disable the API or restrict to custom schema If you don't use the Data API, or if you don't want to expose the `public` schema, you can either disable it entirely or change the automatically exposed schema to one of your choice. See **[Hardening the Data API](/docs/guides/database/hardening-data-api)** for instructions. ## Enforce additional rules on each request Using Row Level Security policies may not always be adequate or sufficient to protect APIs. Here are some common situations where additional protections are necessary: * Enforcing per-IP or per-user rate limits. * Checking custom or additional API keys before allowing further access. * Rejecting requests after exceeding a quota or requiring payment. * Disallowing direct access to certain tables, views or functions in the `public` schema. You can build these cases in your application by creating a Postgres function that will read information from the request and perform additional checks, such as counting the number of requests received or checking that an API key is already registered in your database before serving the response. Define a function like so: ```sql create function public.check_request() returns void language plpgsql security definer as $$ begin -- your logic here end; $$; ``` And register it to run on every Data API request using: ```sql alter role authenticator set pgrst.db_pre_request = 'public.check_request'; ``` This configures the `public.check_request` function to run on every Data API request. To have the changes take effect, you should run: ```sql notify pgrst, 'reload config'; ``` Inside the function you can perform any additional checks on the request headers or JWT and raise an exception to prevent the request from completing. For example, this exception raises a HTTP 402 Payment Required response with a `hint` and additional `X-Powered-By` header: ```sql raise sqlstate 'PGRST' using message = json_build_object( 'code', '123', 'message', 'Payment Required', 'details', 'Quota exceeded', 'hint', 'Upgrade your plan')::text, detail = json_build_object( 'status', 402, 'headers', json_build_object( 'X-Powered-By', 'Nerd Rage'))::text; ``` When raised within the `public.check_request` function, the resulting HTTP response will look like: ```http HTTP/1.1 402 Payment Required Content-Type: application/json; charset=utf-8 X-Powered-By: Nerd Rage { "message": "Payment Required", "details": "Quota exceeded", "hint": "Upgrade your plan", "code": "123" } ``` Use the [JSON operator functions](https://www.postgresql.org/docs/current/functions-json.html) to build rich and dynamic responses from exceptions. If you use a custom HTTP status code like 419, you can supply the `status_text` key in the `detail` clause of the exception to describe the HTTP status. If you're using PostgREST version 11 or lower ([find out your PostgREST version](/dashboard/project/_/settings/infrastructure)) a different and less powerful [syntax](https://postgrest.org/en/stable/references/errors.html#raise-errors-with-http-status-codes) needs to be used. ### Accessing request information Like with RLS policies, you can access information about the request by using the `current_setting()` Postgres function. Here are some examples on how this works: ```sql -- To get all the headers sent in the request SELECT current_setting('request.headers', true)::json; -- To get a single header, you can use JSON arrow operators SELECT current_setting('request.headers', true)::json->>'user-agent'; -- Access Cookies SELECT current_setting('request.cookies', true)::json; ``` | `current_setting()` | Example | Description | | ------------------- | ----------------------------------------------- | ------------------------------------ | | `request.method` | `GET`, `HEAD`, `POST`, `PUT`, `PATCH`, `DELETE` | Request's method | | `request.path` | `table` | Table's path | | `request.path` | `view` | View's path | | `request.path` | `rpc/function` | Functions's path | | `request.headers` | `{ "User-Agent": "...", ... }` | JSON object of the request's headers | | `request.cookies` | `{ "cookieA": "...", "cookieB": "..." }` | JSON object of the request's cookies | | `request.jwt` | `{ "sub": "a7194ea3-...", ... }` | JSON object of the JWT payload | To access the IP address of the client look up the [X-Forwarded-For header](https://developer.mozilla.org/en-US/docs/Web/HTTP/Headers/X-Forwarded-For) in the `request.headers` setting. For example: ```sql SELECT split_part( current_setting('request.headers', true)::json->>'x-forwarded-for', ',', 1); -- takes the client IP before the first comma (,) ``` Read more about [PostgREST's pre-request function](https://postgrest.org/en/stable/references/transactions.html#pre-request). ### Examples # Converting SQL to JavaScript API Many common SQL queries can be written using the JavaScript API, provided by the SDK to wrap Data API calls. Below are a few examples of conversions between SQL and JavaScript patterns. ## Select statement with basic clauses Select a set of columns from a single table with where, order by, and limit clauses. ```sql select first_name, last_name, team_id, age from players where age between 20 and 24 and team_id != 'STL' order by last_name, first_name desc limit 20; ``` ```js const { data, error } = await supabase .from('players') .select('first_name,last_name,team_id,age') .gte('age', 20) .lte('age', 24) .not('team_id', 'eq', 'STL') .order('last_name', { ascending: true }) // or just .order('last_name') .order('first_name', { ascending: false }) .limit(20) ``` ## Select statement with complex Boolean logic clause Select all columns from a single table with a complex where clause: OR AND OR ```sql select * from players where ((team_id = 'CHN' or team_id is null) and (age > 35 or age is null)); ``` ```js const { data, error } = await supabase .from('players') .select() // or .select('*') .or('team_id.eq.CHN,team_id.is.null') .or('age.gt.35,age.is.null') // additional filters imply "AND" ``` Select all columns from a single table with a complex where clause: AND OR AND ```sql select * from players where ((team_id = 'CHN' and age > 35) or (team_id != 'CHN' and age is not null)); ``` ```js const { data, error } = await supabase .from('players') .select() // or .select('*') .or('and(team_id.eq.CHN,age.gt.35),and(team_id.neq.CHN,.not.age.is.null)') ``` ## Resources * [Supabase - Get started for free](https://supabase.com) * [PostgREST Operators](https://postgrest.org/en/stable/api.html#operators) * [Supabase API: JavaScript select](/docs/reference/javascript/select) * [Supabase API: JavaScript modifiers](/docs/reference/javascript/using-modifiers) * [Supabase API: JavaScript filters](/docs/reference/javascript/using-filters) # SQL to REST API Translator Translate SQL queries to HTTP requests and Supabase client code Sometimes it's challenging to translate SQL queries to the equivalent [PostgREST](https://postgrest.org/) request or Supabase client code. Use this tool to help with this translation. # Using Custom Schemas By default, your database has a `public` schema which is automatically exposed on data APIs. ## Creating custom schemas You can create your own custom schema/s by running the following SQL, substituting `myschema` with the name you want to use for your schema: ```sql CREATE SCHEMA myschema; ``` ## Exposing custom schemas You can expose custom database schemas - to do so you need to follow these steps: 1. Go to [API settings](https://supabase.com/dashboard/project/_/settings/api) and add your custom schema to "Exposed schemas". 2. Run the following SQL, substituting `myschema` with your schema name: ```sql GRANT USAGE ON SCHEMA myschema TO anon, authenticated, service_role; GRANT ALL ON ALL TABLES IN SCHEMA myschema TO anon, authenticated, service_role; GRANT ALL ON ALL ROUTINES IN SCHEMA myschema TO anon, authenticated, service_role; GRANT ALL ON ALL SEQUENCES IN SCHEMA myschema TO anon, authenticated, service_role; ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA myschema GRANT ALL ON TABLES TO anon, authenticated, service_role; ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA myschema GRANT ALL ON ROUTINES TO anon, authenticated, service_role; ALTER DEFAULT PRIVILEGES FOR ROLE postgres IN SCHEMA myschema GRANT ALL ON SEQUENCES TO anon, authenticated, service_role; ``` Now you can access these schemas from data APIs: # Auth Use Supabase to authenticate and authorize your users. Supabase Auth makes it easy to implement authentication and authorization in your app. We provide client SDKs and API endpoints to help you create and manage users. Your users can use many popular Auth methods, including password, magic link, one-time password (OTP), social login, and single sign-on (SSO). ## About authentication and authorization Authentication and authorization are the core responsibilities of any Auth system. * **Authentication** means checking that a user is who they say they are. * **Authorization** means checking what resources a user is allowed to access. Supabase Auth uses [JSON Web Tokens (JWTs)](/docs/guides/auth/jwts) for authentication. Auth integrates with Supabase's database features, making it easy to use [Row Level Security (RLS)](/docs/guides/database/postgres/row-level-security) for authorization. ## The Supabase ecosystem You can use Supabase Auth as a standalone product, but it's also built to integrate with the Supabase ecosystem. Auth uses your project's Postgres database under the hood, storing user data and other Auth information in a special schema. You can connect this data to your own tables using triggers and foreign key references. Auth also enables access control to your database's automatically generated [REST API](/docs/guides/api). When using Supabase SDKs, your data requests are automatically sent with the user's Auth Token. The Auth Token scopes database access on a row-by-row level when used along with [RLS policies](/docs/guides/database/postgres/row-level-security). ## Providers Supabase Auth works with many popular Auth methods, including Social and Phone Auth using third-party providers. See the following sections for a list of supported third-party providers. ### Social Auth ### Phone Auth ## Pricing Charges apply to Monthly Active Users (MAU), Monthly Active Third-Party Users (Third-Party MAU), and Monthly Active SSO Users (SSO MAU) and Advanced MFA Add-ons. For a detailed breakdown of how these charges are calculated, refer to the following pages: * [Pricing MAU](/docs/guides/platform/manage-your-usage/monthly-active-users) * [Pricing Third-Party MAU](/docs/guides/platform/manage-your-usage/monthly-active-users-third-party) * [Pricing SSO MAU](/docs/guides/platform/manage-your-usage/monthly-active-users-sso) * [Advanced MFA - Phone](/docs/guides/platform/manage-your-usage/advanced-mfa-phone) # Auth architecture The architecture behind Supabase Auth. There are four major layers to Supabase Auth: 1. [Client layer.](#client-layer) This can be one of the Supabase client SDKs, or manually made HTTP requests using the HTTP client of your choice. 2. Kong API gateway. This is shared between all Supabase products. 3. [Auth service](#auth-service) (formerly known as GoTrue). 4. [Postgres database.](#postgres) This is shared between all Supabase products. ## Client layer The client layer runs in your app. This could be running in many places, including: * Your frontend browser code * Your backend server code * Your native application The client layer provides the functions that you use to sign in and manage users. We recommend using the Supabase client SDKs, which handle: * Configuration and authentication of HTTP calls to the Supabase Auth backend * Persistence, refresh, and removal of Auth Tokens in your app's storage medium * Integration with other Supabase products But at its core, this layer manages the making of HTTP calls, so you could write your own client layer if you wanted to. See the Client SDKs for more information: * [JavaScript](/docs/reference/javascript/introduction) * [Flutter](/docs/reference/dart/introduction) * [Swift](/docs/reference/swift/introduction) * [Python](/docs/reference/python/introduction) * [C#](/docs/reference/csharp/introduction) * [Kotlin](/docs/reference/kotlin/introduction) ## Auth service The [Auth service](https://github.com/supabase/auth) is an Auth API server written and maintained by Supabase. It is a fork of the GoTrue project, originally created by Netlify. When you deploy a new Supabase project, we deploy an instance of this server alongside your database, and inject your database with the required Auth schema. The Auth service is responsible for: * Validating, issuing, and refreshing JWTs * Serving as the intermediary between your app and Auth information in the database * Communicating with external providers for Social Login and SSO ## Postgres Supabase Auth uses the `auth` schema in your Postgres database to store user tables and other information. For security, this schema is not exposed on the auto-generated API. You can connect Auth information to your own objects using [database triggers](/docs/guides/database/postgres/triggers) and [foreign keys](https://www.postgresql.org/docs/current/tutorial-fk.html). Make sure that any views you create for Auth data are adequately protected by [enabling RLS](/docs/guides/database/postgres/row-level-security) or [revoking grants](https://www.postgresql.org/docs/current/sql-revoke.html). # Anonymous Sign-Ins Create and use anonymous users to authenticate with Supabase [Enable Anonymous Sign-Ins](/dashboard/project/_/settings/auth) to build apps which provide users an authenticated experience without requiring users to enter an email address, password, use an OAuth provider or provide any other PII (Personally Identifiable Information). Later, when ready, the user can link an authentication method to their account. Anonymous sign-ins can be used to build: * E-commerce applications, such as shopping carts before check-out * Full-feature demos without collecting personal information * Temporary or throw-away accounts ## Sign in anonymously ## Convert an anonymous user to a permanent user Converting an anonymous user to a permanent user requires [linking an identity](/docs/guides/auth/auth-identity-linking#manual-linking-beta) to the user. This requires you to [enable manual linking](/dashboard/project/_/settings/auth) in your Supabase project. ### Link an email / phone identity ### Link an OAuth identity ## Access control An anonymous user assumes the `authenticated` role just like a permanent user. You can use row-level security (RLS) policies to differentiate between an anonymous user and a permanent user by checking for the `is_anonymous` claim in the JWT returned by `auth.jwt()`: ```sql create policy "Only permanent users can post to the news feed" on news_feed as restrictive for insert to authenticated with check ((select (auth.jwt()->>'is_anonymous')::boolean) is false ); create policy "Anonymous and permanent users can view the news feed" on news_feed for select to authenticated using ( true ); ``` ## Resolving identity conflicts Depending on your application requirements, data conflicts can arise when an anonymous user is converted to a permanent user. For example, in the context of an e-commerce application, an anonymous user would be allowed to add items to the shopping cart without signing up / signing in. When they decide to sign-in to an existing account, you will need to decide how you want to resolve data conflicts in the shopping cart: 1. Overwrite the items in the cart with those in the existing account 2. Overwrite the items in the cart with those from the anonymous user 3. Merge the items in the cart together ### Linking an anonymous user to an existing account In some cases, you may need to link an anonymous user to an existing account rather than creating a new permanent account. This process requires manual handling of potential conflicts. Here's a general approach: ```javascript // 1. Sign in anonymously (assuming the user is already signed in anonymously) const { data: anonData, error: anonError } = await supabase.auth.getSession() // 2. Attempt to update the user with the existing email const { data: updateData, error: updateError } = await supabase.auth.updateUser({ email: 'valid.email@supabase.io', }) // 3. Handle the error (since the email belongs to an existing user) if (updateError) { console.log('This email belongs to an existing user. Please sign in to that account.') // 4. Sign in to the existing account const { data: { user: existingUser }, error: signInError, } = await supabase.auth.signInWithPassword({ email: 'valid.email@supabase.io', password: 'user_password', }) if (existingUser) { // 5. Reassign entities tied to the anonymous user // This step will vary based on your specific use case and data model const { data: reassignData, error: reassignError } = await supabase .from('your_table') .update({ user_id: existingUser.id }) .eq('user_id', anonData.session.user.id) // 6. Implement your chosen conflict resolution strategy // This could involve merging data, overwriting, or other custom logic await resolveDataConflicts(anonData.session.user.id, existingUser.id) } } // Helper function to resolve data conflicts (implement based on your strategy) async function resolveDataConflicts(anonymousUserId, existingUserId) { // Implement your conflict resolution logic here // This could involve ignoring the anonymous user's metadata, overwriting the existing user's metadata, or merging the data of both the anonymous and existing user. } ``` ## Abuse prevention and rate limits Since anonymous users are stored in your database, bad actors can abuse the endpoint to increase your database size drastically. It is strongly recommended to [enable invisible CAPTCHA or Cloudflare Turnstile](/docs/guides/auth/auth-captcha) to prevent abuse for anonymous sign-ins. An IP-based rate limit is enforced at 30 requests per hour which can be modified in your [dashboard](/dashboard/project/_/auth/rate-limits). You can refer to the full list of rate limits [here](/docs/guides/platform/going-into-prod#rate-limiting-resource-allocation--abuse-prevention). ## Automatic cleanup Automatic cleanup of anonymous users is currently not available. Instead, you can delete anonymous users from your project by running the following SQL: ```sql -- deletes anonymous users created more than 30 days ago delete from auth.users where is_anonymous is true and created_at < now() - interval '30 days'; ``` ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Supabase Flutter Client](https://github.com/supabase/supabase-flutter) * [Supabase Kotlin Client](https://github.com/supabase-community/supabase-kt) # Enable CAPTCHA Protection Supabase provides you with the option of adding CAPTCHA to your sign-in, sign-up, and password reset forms. This keeps your website safe from bots and malicious scripts. Supabase authentication has support for [hCaptcha](https://www.hcaptcha.com/) and [Cloudflare Turnstile](https://www.cloudflare.com/products/turnstile/). ## Sign up for CAPTCHA ## Enable CAPTCHA protection for your Supabase project Navigate to the **[Auth](https://supabase.com/dashboard/project/_/settings/auth)** section of your Project Settings in the Supabase Dashboard and find the **Enable CAPTCHA protection** toggle under Settings > Authentication > Bot and Abuse Protection > Enable CAPTCHA protection. Select your CAPTCHA provider from the dropdown, enter your CAPTCHA **Secret key**, and click **Save**. ## Add the CAPTCHA frontend component The frontend requires some changes to provide the CAPTCHA on-screen for the user. This example uses React and the corresponding CAPTCHA React component, but both CAPTCHA providers can be used with any JavaScript framework. Run the application and you should now be provided with a CAPTCHA challenge. # Passwordless email logins Email logins using Magic Links or One-Time Passwords (OTPs) Supabase Auth provides several passwordless login methods. Passwordless logins allow users to sign in without a password, by clicking a confirmation link or entering a verification code. Passwordless login can: * Improve the user experience by not requiring users to create and remember a password * Increase security by reducing the risk of password-related security breaches * Reduce support burden of dealing with password resets and other password-related flows Supabase Auth offers two passwordless login methods that use the user's email address: * [Magic Link](#with-magic-link) * [OTP](#with-otp) ## With Magic Link Magic Links are a form of passwordless login where users click on a link sent to their email address to log in to their accounts. Magic Links only work with email addresses and are one-time use only. ### Enabling Magic Link Email authentication methods, including Magic Links, are enabled by default. Configure the Site URL and any additional redirect URLs. These are the only URLs that are allowed as redirect destinations after the user clicks a Magic Link. You can change the URLs on the [Auth Providers page](/dashboard/project/_/auth/providers) for hosted projects, or in the [configuration file](/docs/guides/cli/config#auth.additional_redirect_urls) for self-hosted projects. By default, a user can only request a magic link once every and they expire after . ### Signing in with Magic Link Call the "sign in with OTP" method from the client library. Though the method is labelled "OTP", it sends a Magic Link by default. The two methods differ only in the content of the confirmation email sent to the user. If the user hasn't signed up yet, they are automatically signed up by default. To prevent this, set the `shouldCreateUser` option to `false`. That's it for the implicit flow. If you're using PKCE flow, edit the Magic Link [email template](/docs/guides/auth/auth-email-templates) to send a token hash: ```html

Magic Link

Follow this link to login:

Log In

``` At the `/auth/confirm` endpoint, exchange the hash for the session: ```js import { createClient } from '@supabase/supabase-js' const supabase = createClient('url', 'anonKey') // ---cut--- const { error } = await supabase.auth.verifyOtp({ token_hash: 'hash', type: 'email', }) ``` ## With OTP Email one-time passwords (OTP) are a form of passwordless login where users key in a six digit code sent to their email address to log in to their accounts. ### Enabling email OTP Email authentication methods, including Email OTPs, are enabled by default. Email OTPs share an implementation with Magic Links. To send an OTP instead of a Magic Link, alter the **Magic Link** email template. For a hosted Supabase project, go to [Email Templates](/dashboard/project/_/auth/templates) in the Dashboard. For a self-hosted project or local development, see the [Email Templates guide](/docs/guides/auth/auth-email-templates). Modify the template to include the `{{ .Token }}` variable, for example: ```html

One time login code

Please enter this code: {{ .Token }}

``` By default, a user can only request an OTP once every and they expire after . This is configurable via `Auth > Providers > Email > Email OTP Expiration`. An expiry duration of more than 86400 seconds (one day) is disallowed to guard against brute force attacks. The longer an OTP remains valid, the more time an attacker has to attempt brute force attacks. If the OTP is valid for several days, an attacker might have more opportunities to guess the correct OTP through repeated attempts. ### Signing in with email OTP #### Step 1: Send the user an OTP code Get the user's email and call the "sign in with OTP" method from your client library. If the user hasn't signed up yet, they are automatically signed up by default. To prevent this, set the `shouldCreateUser` option to `false`. If the request is successful, you receive a response with `error: null` and a `data` object where both `user` and `session` are null. Let the user know to check their email inbox. ```json { "data": { "user": null, "session": null }, "error": null } ``` #### Step 2: Verify the OTP to create a session Provide an input field for the user to enter their one-time code. Call the "verify OTP" method from your client library with the user's email address, the code, and a type of `email`: If successful, the user is now logged in, and you receive a valid session that looks like: ```json { "access_token": "eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJhdWQiOiJhdXRoZW50aWNhdGVkIiwiZXhwIjoxNjI3MjkxNTc3LCJzdWIiOiJmYTA2NTQ1Zi1kYmI1LTQxY2EtYjk1NC1kOGUyOTg4YzcxOTEiLCJlbWFpbCI6IiIsInBob25lIjoiNjU4NzUyMjAyOSIsImFwcF9tZXRhZGF0YSI6eyJwcm92aWRlciI6InBob25lIn0sInVzZXJfbWV0YWRhdGEiOnt9LCJyb2xlIjoiYXV0aGVudGljYXRlZCJ9.1BqRi0NbS_yr1f6hnr4q3s1ylMR3c1vkiJ4e_N55dhM", "token_type": "bearer", "expires_in": 3600, "refresh_token": "LSp8LglPPvf0DxGMSj-vaQ", "user": {...} } ``` # Email Templates Learn how to manage the email templates in Supabase. You can customize the email messages used for the authentication flows. You can edit the following email templates: * Confirm signup * Invite user * Magic Link * Change Email Address * Reset Password ## Terminology The templating system provides the following variables for use: | Name | Description | | ------------------------ | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | `{{ .ConfirmationURL }}` | Contains the confirmation URL. For example, a signup confirmation URL would look like: `https://project-ref.supabase.co/auth/v1/verify?token={{ .TokenHash }}&type=email&redirect_to=https://example.com/path` . | | `{{ .Token }}` | Contains a 6-digit One-Time-Password (OTP) that can be used instead of the `{{. ConfirmationURL }}` . | | `{{ .TokenHash }}` | Contains a hashed version of the `{{ .Token }}`. This is useful for constructing your own email link in the email template. | | `{{ .SiteURL }}` | Contains your application's Site URL. This can be configured in your project's [authentication settings](/dashboard/project/_/auth/url-configuration). | | `{{ .RedirectTo }}` | Contains the redirect URL passed when `signUp`, `signInWithOtp`, `signInWithOAuth`, `resetPasswordForEmail` or `inviteUserByEmail` is called. The redirect URL allow list can be configured in your project's [authentication settings](/dashboard/project/_/auth/url-configuration). | | `{{ .Data }}` | Contains metadata from `auth.users.user_metadata`. Use this to personalize the email message. | ## Editing email templates On hosted Supabase projects, edit your email templates on the [Email Templates](/dashboard/project/_/auth/templates) page. On self-hosted projects or in local development, edit your [configuration files](/docs/guides/local-development/customizing-email-templates). ## Mobile deep linking For mobile applications, you might need to link or redirect to a specific page within your app. See the [Mobile Deep Linking guide](/docs/guides/auth/native-mobile-deep-linking) to set this up. ## Limitations ### Email prefetching Certain email providers may have spam detection or other security features that prefetch URL links from incoming emails (e.g. [Safe Links in Microsoft Defender for Office 365](https://learn.microsoft.com/en-us/microsoft-365/security/office-365-security/safe-links-about?view=o365-worldwide)). In this scenario, the `{{ .ConfirmationURL }}` sent will be consumed instantly which leads to a "Token has expired or is invalid" error. To guard against this: * Use an email OTP instead by including `{{ .Token }}` in the email template. * Create your own custom email link to redirect the user to a page where they can click on a button to confirm the action. For example, you can include the following in your email template: ```html Confirm your signup ``` The user should be brought to a page on your site where they can confirm the action by clicking a button. The button should contain the actual confirmation link which can be obtained from parsing the `confirmation_url={{ .ConfirmationURL }}` query parameter in the URL. ### Email tracking If you are using an external email provider that enables "email tracking", the links inside the Supabase email templates will be overwritten and won't perform as expected. We recommend disabling email tracking to ensure email links are not overwritten. ### Redirecting the user to a server-side endpoint If you intend to use [Server-side rendering](/docs/guides/auth/server-side-rendering), you might want the email link to redirect the user to a server-side endpoint to check if they are authenticated before returning the page. However, the default email link will redirect the user after verification to the redirect URL with the session in the query fragments. Since the session is returned in the query fragments by default, you won't be able to access it on the server-side. You can customize the email link in the email template to redirect the user to a server-side endpoint successfully. For example: ```html Accept the invite ``` When the user clicks on the link, the request will hit `https://api.example.com/v1/authenticate` and you can grab the `token_hash`, `type` and `redirect_to` query parameters from the URL. Then, you can call the [`verifyOtp`](/docs/reference/javascript/auth-verifyotp) method to get back an authenticated session before redirecting the user back to the client. Since the `verifyOtp` method makes a `POST` request to Supabase Auth to verify the user, the session will be returned in the response body, which can be read by the server. For example: ```ts import { createClient, type EmailOtpType } from '@supabase/supabase-js' const supabase = createClient('https://your-project-id.supabase.co', 'your-anon-key') // ---cut--- const { token_hash, type } = Object.fromEntries(new URLSearchParams(window.location.search)) const { data: { session }, error, } = await supabase.auth.verifyOtp({ token_hash, type: type as EmailOtpType }) // subsequently redirect the user back to the client using the redirect_to param // ... ``` ## Customization Supabase Auth makes use of [Go Templates](https://pkg.go.dev/text/template). This means it is possible to conditionally render information based on template properties. ### Send different email to early access users Send a different email to users who signed up via an early access domain (`https://www.earlyaccess.trial.com`). {{ if eq .Data.Domain "https://www.example.com" }}

Welcome to Our Database Service!

Dear Developer,

Welcome to Billy, the scalable developer platform!

Best Regards,
Billy Team

{{ else if eq .Data.Domain "https://www.earlyaccess.trial.com" }}

Welcome to Our Database Service!

Dear Developer,

Welcome Billy, the scalable developer platform!

As an early access member, you have access to select features like Point To Space Restoration.

Best Regards,
Billy Team

{{ end }} # Auth Helpers Working with server-side frameworks is slightly different to client-side frameworks. In this section we cover the various ways of handling server-side authentication and demonstrate how to use the Supabase helper-libraries to make the process more seamless. ## Status The Auth Helpers are `deprecated`. Use the new `@supabase/ssr` package for Server Side Authentication. Use the [migration doc](/docs/guides/auth/server-side/migrating-to-ssr-from-auth-helpers) to learn more. ## Additional links * [Source code](https://github.com/supabase/auth-helpers) * [Known bugs and issues](https://github.com/supabase/auth-helpers/issues) # Auth UI Auth UI is a pre-built React component for authenticating users. It supports custom themes and extensible styles to match your brand and aesthetic. ## Set up Auth UI Install the latest version of [supabase-js](/docs/reference/javascript) and the Auth UI package: ```bash npm install @supabase/supabase-js @supabase/auth-ui-react @supabase/auth-ui-shared ``` ### Import the Auth component Pass `supabaseClient` from `@supabase/supabase-js` as a prop to the component. ```js /src/index.js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' const supabase = createClient('', '') const App = () => ``` This renders the Auth component without any styling. We recommend using one of the predefined themes to style the UI. Import the theme you want to use and pass it to the `appearance.theme` prop. ```js import { Auth } from '@supabase/auth-ui-react' import { // Import predefined theme ThemeSupa, } from '@supabase/auth-ui-shared' const supabase = createClient( '', '' ) const App = () => ( ) ``` ### Social providers The Auth component also supports login with [official social providers](../../auth#providers). ```js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' import { ThemeSupa } from '@supabase/auth-ui-shared' const supabase = createClient('', '') const App = () => ( ) ``` ### Options Options are available via `queryParams`: ```jsx ``` ### Provider scopes Provider Scopes can be requested through `providerScope`; ```jsx ``` ### Supported views The Auth component is currently shipped with the following views: * [Email Login](../auth-email) * [Magic Link login](../auth-magic-link) * [Social Login](../social-login) * Update password * Forgotten password We are planning on adding more views in the future. Follow along on that [repo](https://github.com/supabase/auth-ui). ## Customization There are several ways to customize Auth UI: * Use one of the [predefined themes](#predefined-themes) that comes with Auth UI * Extend a theme by [overriding the variable tokens](#override-themes) in a theme * [Create your own theme](#create-theme) * [Use your own CSS classes](#custom-css-classes) * [Use inline styles](#custom-inline-styles) * [Use your own labels](#custom-labels) ### Predefined themes Auth UI comes with several themes to customize the appearance. Each predefined theme comes with at least two variations, a `default` variation, and a `dark` variation. You can switch between these themes using the `theme` prop. Import the theme you want to use and pass it to the `appearance.theme` prop. ```js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' import { ThemeSupa } from '@supabase/auth-ui-shared' const supabase = createClient( '', '' ) const App = () => ( ) ``` ### Switch theme variations Auth UI comes with two theme variations: `default` and `dark`. You can switch between these themes with the `theme` prop. ```js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' import { ThemeSupa } from '@supabase/auth-ui-shared' const supabase = createClient( '', '' ) const App = () => ( ) ``` If you don't pass a value to `theme` it uses the `"default"` theme. You can pass `"dark"` to the theme prop to switch to the `dark` theme. If your theme has other variations, use the name of the variation in this prop. ### Override themes Auth UI themes can be overridden using variable tokens. See the [list of variable tokens](https://github.com/supabase/auth-ui/blob/main/packages/shared/src/theming/Themes.ts). ```js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' import { ThemeSupa } from '@supabase/auth-ui-shared' const supabase = createClient('', '') const App = () => ( ) ``` If you created your own theme, you may not need to override any of them. ### Create your own theme \[#create-theme] You can create your own theme by following the same structure within a `appearance.theme` property. See the list of [tokens within a theme](https://github.com/supabase/auth-ui/blob/main/packages/shared/src/theming/Themes.ts). ```js /src/index.js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' const supabase = createClient('', '') const customTheme = { default: { colors: { brand: 'hsl(153 60.0% 53.0%)', brandAccent: 'hsl(154 54.8% 45.1%)', brandButtonText: 'white', // .. }, }, dark: { colors: { brandButtonText: 'white', defaultButtonBackground: '#2e2e2e', defaultButtonBackgroundHover: '#3e3e3e', //.. }, }, // You can also add more theme variations with different names. evenDarker: { colors: { brandButtonText: 'white', defaultButtonBackground: '#1e1e1e', defaultButtonBackgroundHover: '#2e2e2e', //.. }, }, } const App = () => ( ) ``` You can switch between different variations of your theme with the ["theme" prop](#switch-theme-variations). ### Custom CSS classes \[#custom-css-classes] You can use custom CSS classes for the following elements: `"button"`, `"container"`, `"anchor"`, `"divider"`, `"label"`, `"input"`, `"loader"`, `"message"`. ```js /src/index.js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' const supabase = createClient('', '') const App = () => ( ) ``` ### Custom inline CSS \[#custom-inline-styles] You can use custom CSS inline styles for the following elements: `"button"`, `"container"`, `"anchor"`, `"divider"`, `"label"`, `"input"`, `"loader"`, `"message"`. ```js /src/index.js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' const supabase = createClient('', '') const App = () => ( ) ``` ### Custom labels \[#custom-labels] You can use custom labels with `localization.variables` like so: ```js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' const supabase = createClient('', '') const App = () => ( ) ``` A full list of the available variables is below: ### Hiding links \[#hiding-links] You can hide links by setting the `showLinks` prop to `false` ```js import { createClient } from '@supabase/supabase-js' import { Auth } from '@supabase/auth-ui-react' const supabase = createClient('', '') const App = () => ``` Setting `showLinks` to `false` will hide the following links: * Don't have an account? Sign up * Already have an account? Sign in * Send a magic link email * Forgot your password? ### Sign in and sign up views Add `sign_in` or `sign_up` views with the `view` prop: # Flutter Auth UI Flutter Auth UI is a Flutter package containing pre-built widgets for authenticating users. It is unstyled and can match your brand and aesthetic. ![Flutter Auth UI](https://raw.githubusercontent.com/supabase-community/flutter-auth-ui/main/screenshots/supabase_auth_ui.png) ## Add Flutter Auth UI Add the latest version of the package [supabase-auth-ui](https://pub.dev/packages/supabase_auth_ui) to pubspec.yaml: ```bash flutter pub add supabase_auth_ui ``` ### Initialize the Flutter Auth package ```dart import 'package:flutter/material.dart'; import 'package:supabase_auth_ui/supabase_auth_ui.dart'; void main() async { await Supabase.initialize( url: dotenv.get('SUPABASE_URL'), anonKey: dotenv.get('SUPABASE_ANON_KEY'), ); runApp(const MyApp()); } ``` ### Email Auth Use a `SupaEmailAuth` widget to create an email and password signin and signup form. It also contains a button to toggle to display a forgot password form. You can pass `metadataFields` to add additional fields to the form to pass as metadata to Supabase. ```dart SupaEmailAuth( redirectTo: kIsWeb ? null : 'io.mydomain.myapp://callback', onSignInComplete: (response) {}, onSignUpComplete: (response) {}, metadataFields: [ MetaDataField( prefixIcon: const Icon(Icons.person), label: 'Username', key: 'username', validator: (val) { if (val == null || val.isEmpty) { return 'Please enter something'; } return null; }, ), ], ) ``` ### Magic link Auth Use `SupaMagicAuth` widget to create a magic link signIn form. ```dart SupaMagicAuth( redirectUrl: kIsWeb ? null : 'io.mydomain.myapp://callback', onSuccess: (Session response) {}, onError: (error) {}, ) ``` ### Reset password Use `SupaResetPassword` to create a password reset form. ```dart SupaResetPassword( accessToken: supabase.auth.currentSession?.accessToken, onSuccess: (UserResponse response) {}, onError: (error) {}, ) ``` ### Phone Auth Use `SupaPhoneAuth` to create a phone authentication form. ```dart SupaPhoneAuth( authAction: SupaAuthAction.signUp, onSuccess: (AuthResponse response) {}, ), ``` ### Social Auth The package supports login with [official social providers](../../auth#providers). Use `SupaSocialsAuth` to create list of social login buttons. ```dart SupaSocialsAuth( socialProviders: [ OAuthProvider.apple, OAuthProvider.google, ], colored: true, redirectUrl: kIsWeb ? null : 'io.mydomain.myapp://callback', onSuccess: (Session response) {}, onError: (error) {}, ) ``` ### Theming This package uses plain Flutter components allowing you to control the appearance of the components using your own theme. # Supabase Auth with Next.js Pages Directory # Supabase Auth with the Next.js App Router # Supabase Auth with Remix # Supabase Auth with SvelteKit # Auth Hooks Use HTTP or Postgres Functions to customize your authentication flow ## What is a hook A hook is an endpoint that allows you to alter the default Supabase Auth flow at specific execution points. Developers can use hooks to add custom behavior that's not supported natively. Hooks help you: * Track the origin of user signups by adding metadata * Improve security by adding additional checks to password and multi-factor authentication * Support legacy systems by integrating with identity credentials from external authentication systems * Add additional custom claims to your JWT * Send authentication emails or SMS messages through a custom provider The following hooks are available: | Hook | Available on Plan | | ---------------------------------------------------------------------------------------- | -------------------- | | [Custom Access Token](/docs/guides/auth/auth-hooks/custom-access-token-hook) | Free, Pro | | [Send SMS](/docs/guides/auth/auth-hooks/send-sms-hook) | Free, Pro | | [Send Email](/docs/guides/auth/auth-hooks/send-email-hook) | Free, Pro | | [MFA Verification Attempt](/docs/guides/auth/auth-hooks/mfa-verification-hook) | Teams and Enterprise | | [Password Verification Attempt](/docs/guides/auth/auth-hooks/password-verification-hook) | Teams and Enterprise | Supabase supports 2 ways to [configure a hook](/dashboard/project/_/auth/hooks) in your project: ## Security model Sign the payload and grant permissions selectively in order to guard the integrity of the payload. ## Using Hooks ### Developing Let us develop a Hook locally and then deploy it to the cloud. As a recap, here’s a list of available Hooks | Hook | Suggested Function Name | When it is called | What it Does | | ----------------------------- | ------------------------------- | -------------------------------------------------- | --------------------------------------------------------------------------------------------------------- | | Send SMS | `send_sms` | Each time an SMS is sent | Allows you to customize message content and SMS Provider | | Send Email | `send_email` | Each time an Email is sent | Allows you to customize message content and Email Provider | | Custom Access Token | `custom_access_token` | Each time a new JWT is created | Returns the claims you wish to be present in the JWT. | | MFA Verification Attempt | `mfa_verification_attempt` | Each time a user tries to verify an MFA factor. | Returns a decision on whether to reject the attempt and future ones, or to allow the user to keep trying. | | Password Verification Attempt | `password_verification_attempt` | Each time a user tries to sign in with a password. | Return a decision whether to allow the user to reject the attempt, or to allow the user to keep trying. | Edit `config.toml` to set up the Auth Hook locally. ### Deploying In the dashboard, navigate to [`Authentication > Hooks`](/dashboard/project/_/auth/hooks) and select the appropriate function type (SQL or HTTP) from the dropdown menu. ### Error handling You should return an error when facing a runtime error. Runtime errors are specific to your application and arise from specific business rules rather than programmer errors. Runtime errors could happen when: * The user does not have appropriate permissions * The event payload received does not have required claims. * The user has performed an action which violates a business rule. * The email or phone provider used in the webhook returned an error. Outside of runtime errors, both HTTP Hooks and Postgres Hooks return timeout errors. Postgres Hooks have seconds to complete processing while HTTP Hooks should complete in seconds. Both HTTP Hooks and Postgres Hooks are run in a transaction do limit the duration of execution to avoid delays in authentication process. ## Available Hooks Each Hook description contains an example JSON Schema which you can use in conjunction with [JSON Schema Faker](https://json-schema-faker.js.org/) in order to generate a mock payload. For HTTP Hooks, you can also use [the Standard Webhooks Testing Tool](https://www.standardwebhooks.com/simulate) to simulate a request. # Custom Access Token Hook Customize the access token issued by Supabase Auth The custom access token hook runs before a token is issued and allows you to add additional claims based on the authentication method used. Claims returned must conform to our specification. Supabase Auth will check for these claims after the hook is run and return an error if they are not present. These are the fields currently available on an access token: Required Claims: `iss`, `aud`, `exp`, `iat`, `sub`, `role`, `aal`, `session_id` Optional Claims: `jti`, `nbf`, `app_metadata`, `user_metadata`, `amr`, `email`, `phone` **Inputs** | Field | Type | Description | | ----------------------- | -------- | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | `user_id` | `string` | Unique identifier for the user attempting to sign in. | | `claims` | `object` | Claims which are included in the access token. | | `authentication_method` | `string` | The authentication method used to request the access token. Possible values include: `oauth`, `password`, `otp`, `totp`, `recovery`, `invite`, `sso/saml`, `magiclink`, `email/signup`, `email_change`, `token_refresh`, `anonymous`. | **Outputs** Return these only if your hook processed the input without errors. | Field | Type | Description | | -------- | -------- | ----------------------------------------------- | | `claims` | `object` | The updated claims after the hook has been run. | # MFA Verification Hook You can add additional checks to the [Supabase MFA implementation](/docs/guides/auth/auth-mfa) with hooks. For example, you can: * Limit the number of verification attempts performed over a period of time. * Sign out users who have too many invalid verification attempts. * Count, rate limit, or ban sign-ins. **Inputs** Supabase Auth will send a payload containing these fields to your hook: | Field | Type | Description | | ------------- | --------- | --------------------------------------------------------------------------------------------------------------------------------- | | `factor_id` | `string` | Unique identifier for the MFA factor being verified | | `factor_type` | `string` | `totp` or `phone` | | `user_id` | `string` | Unique identifier for the user | | `valid` | `boolean` | Whether the verification attempt was valid. For TOTP, this means that the six digit code was correct (true) or incorrect (false). | **Outputs** Return this if your hook processed the input without errors. | Field | Type | Description | | ---------- | -------- | --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | `decision` | `string` | The decision on whether to allow authentication to move forward. Use `reject` to deny the verification attempt and log the user out of all active sessions. Use `continue` to use the default Supabase Auth behavior. | | `message` | `string` | The message to show the user if the decision was `reject`. | ```json { "decision": "reject", "message": "You have exceeded maximum number of MFA attempts." } ``` # Password Verification Hook Your company wishes to increase security beyond the requirements of the default password implementation in order to fulfill security or compliance requirements. You plan to track the status of a password sign-in attempt and take action via an email or a restriction on logins where necessary. As this hook runs on unauthenticated requests, malicious users can abuse the hook by calling it multiple times. Pay extra care when using the hook as you can unintentionally block legitimate users from accessing your application. Check if a password is valid prior to taking any additional action to ensure the user is legitimate. Where possible, send an email or notification instead of blocking the user. **Inputs** | Field | Type | Description | | --------- | --------- | ----------------------------------------------------------------------------------------------- | | `user_id` | `string` | Unique identifier for the user attempting to sign in. Correlate this to the `auth.users` table. | | `valid` | `boolean` | Whether the password verification attempt was valid. | **Outputs** Return these only if your hook processed the input without errors. | Field | Type | Description | | -------------------- | --------- | --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | `decision` | `string` | The decision on whether to allow authentication to move forward. Use `reject` to deny the verification attempt and log the user out of all active sessions. Use `continue` to use the default Supabase Auth behavior. | | `message` | `string` | The message to show the user if the decision was `reject`. | | `should_logout_user` | `boolean` | Whether to log out the user if a `reject` decision is issued. Has no effect when a `continue` decision is issued. | ```json { "decision": "reject", "message": "You have exceeded maximum number of password sign-in attempts.", "should_logout_user": "false" } ``` # Send Email Hook Use a custom email provider to send authentication messages The Send Email Hook runs before an email is sent and allows for flexibility around email sending. You can use this hook to configure a back-up email provider or add internationalization to your emails. ## Email sending behavior Email sending depends on two settings: Email Provider and Auth Hook status. | Email Provider | Auth Hook | Result | | -------------- | --------- | -------------------------------------------------------------------- | | Enabled | Enabled | Auth Hook handles email sending (SMTP not used) | | Enabled | Disabled | SMTP handles email sending (custom if configured, default otherwise) | | Disabled | Enabled | Email Signups Disabled | | Disabled | Disabled | Email Signups Disabled | **Inputs** | Field | Type | Description | | ------- | ------------------------------------------------- | ---------------------------------------------------------------------------------- | | `user` | [`User`](/docs/guides/auth/users#the-user-object) | The user attempting to sign in. | | `email` | `object` | Metadata specific to the email sending process. Includes the OTP and `token_hash`. | **Outputs** * No outputs are required. An empty response with a status code of 200 is taken as a successful response. # Send SMS Hook Use a custom SMS provider to send authentication messages Runs before a message is sent. Use the hook to: * Use a regional SMS Provider * Use alternate messaging channels such as WhatsApp * Adjust the message body to include platform specific fields such as the [`AppHash`](https://developers.google.com/identity/sms-retriever/overview) **Inputs** | Field | Type | Description | | ------ | ------------------------------------------------- | --------------------------------------------------------------- | | `user` | [`User`](/docs/guides/auth/users#the-user-object) | The user attempting to sign in. | | `sms` | `object` | Metadata specific to the SMS sending process. Includes the OTP. | **Outputs** * No outputs are required. An empty response with a status code of 200 is taken as a successful response. # Identity Linking Manage the identities associated with your user ## Identity linking strategies Currently, Supabase Auth supports 2 strategies to link an identity to a user: 1. [Automatic Linking](#automatic-linking) 2. [Manual Linking](#manual-linking-beta) ### Automatic linking Supabase Auth automatically links identities with the same email address to a single user. This helps to improve the user experience when multiple OAuth login options are presented since the user does not need to remember which OAuth account they used to sign up with. When a new user signs in with OAuth, Supabase Auth will attempt to look for an existing user that uses the same email address. If a match is found, the new identity is linked to the user. In order for automatic linking to correctly identify the user for linking, Supabase Auth needs to ensure that all user emails are unique. It would also be an insecure practice to automatically link an identity to a user with an unverified email address since that could lead to pre-account takeover attacks. To prevent this from happening, when a new identity can be linked to an existing user, Supabase Auth will remove any other unconfirmed identities linked to an existing user. Users that signed up with [SAML SSO](/docs/guides/auth/sso/auth-sso-saml) will not be considered as targets for automatic linking. ### Manual linking (beta) In the example above, the user will be redirected to Google to complete the OAuth2.0 flow. Once the OAuth2.0 flow has completed successfully, the user will be redirected back to the application and the Google identity will be linked to the user. You can enable manual linking from your project's authentication [configuration options](/dashboard/project/_/settings/auth) or by setting the environment variable `GOTRUE_SECURITY_MANUAL_LINKING_ENABLED: true` when self-hosting. ## Unlink an identity ## Frequently asked questions ### How to add email/password login to an OAuth account? Call the `updateUser({ password: 'validpassword'})` to add email with password authentication to an account created with an OAuth provider (Google, GitHub, etc.). ### Can you sign up with email if already using OAuth? If you try to create an email account after previously signing up with OAuth using the same email, you'll receive an obfuscated user response with no verification email sent. This prevents user enumeration attacks. # Multi-Factor Authentication Multi-factor authentication (MFA), sometimes called two-factor authentication (2FA), adds an additional layer of security to your application by verifying their identity through additional verification steps. It is considered a best practice to use MFA for your applications. Users with weak passwords or compromised social login accounts are prone to malicious account takeovers. These can be prevented with MFA because they require the user to provide proof of both of these: * Something they know. Password, or access to a social-login account. * Something they have. Access to an authenticator app (a.k.a. TOTP) or a mobile phone. ## Overview Supabase Auth implements MFA via two methods: App Authenticator, which makes use of a Time based-one Time Password, and phone messaging, which makes use of a code generated by Supabase Auth. Applications using MFA require two important flows: 1. **Enrollment flow.** This lets users set up and control MFA in your app. 2. **Authentication flow.** This lets users sign in using any factors after the conventional login step. Supabase Auth provides: * **Enrollment API** - build rich user interfaces for adding and removing factors. * **Challenge and Verify APIs** - securely verify that the user has access to a factor. * **List Factors API** - build rich user interfaces for signing in with additional factors. You can control access to the Enrollment API as well as the Challenge and Verify APIs via the Supabase Dashboard. A setting of `Verification Disabled` will disable both the challenge API and the verification API. These sets of APIs let you control the MFA experience that works for you. You can create flows where MFA is optional, mandatory for all, or only specific groups of users. Once users have enrolled or signed-in with a factor, Supabase Auth adds additional metadata to the user's access token (JWT) that your application can use to allow or deny access. This information is represented by an [Authenticator Assurance Level](https://pages.nist.gov/800-63-3-Implementation-Resources/63B/AAL/), a standard measure about the assurance of the user's identity Supabase Auth has for that particular session. There are two levels recognized today: 1. **Assurance Level 1: `aal1`** Means that the user's identity was verified using a conventional login method such as email+password, magic link, one-time password, phone auth or social login. 2. **Assurance Level 2: `aal2`** Means that the user's identity was additionally verified using at least one second factor, such as a TOTP code or One-Time Password code. This assurance level is encoded in the `aal` claim in the JWT associated with the user. By decoding this value you can create custom authorization rules in your frontend, backend, and database that will enforce the MFA policy that works for your application. JWTs without an `aal` claim are at the `aal1` level. ## Adding to your app Adding MFA to your app involves these four steps: 1. **Add enrollment flow.** You need to provide a UI within your app that your users will be able to set-up MFA in. You can add this right after sign-up, or as part of a separate flow in the settings portion of your app. 2. **Add unenroll flow.** You need to support a UI through which users can see existing devices and unenroll devices which are no longer relevant. 3. **Add challenge step to login.** If a user has set-up MFA, your app's login flow needs to present a challenge screen to the user asking them to prove they have access to the additional factor. 4. **Enforce rules for MFA logins.** Once your users have a way to enroll and log in with MFA, you need to enforce authorization rules across your app: on the frontend, backend, API servers or Row-Level Security policies. The enrollment flow and the challenge steps differ by factor and are covered on a separate page. Visit the [Phone](/docs/guides/auth/auth-mfa/phone) or [App Authenticator](/docs/guides/auth/auth-mfa/totp) pages to see how to add the flows for the respective factors. You can combine both flows and allow for use of both Phone and App Authenticator Factors. ### Add unenroll flow The unenroll process is the same for both Phone and TOTP factors. An unenroll flow provides a UI for users to manage and unenroll factors linked to their accounts. Most applications do so via a factor management page where users can view and unlink selected factors. When a user unenrolls a factor, call `supabase.auth.mfa.unenroll()` with the ID of the factor. For example, call: ```js import { createClient } from '@supabase/supabase-js' const supabase = createClient('https://your-project-id.supabase.co', 'your-anon-key') // ---cut--- supabase.auth.mfa.unenroll({ factorId: 'd30fd651-184e-4748-a928-0a4b9be1d429' }) ``` to unenroll a factor with ID `d30fd651-184e-4748-a928-0a4b9be1d429`. ### Enforce rules for MFA logins Adding MFA to your app's UI does not in-and-of-itself offer a higher level of security to your users. You also need to enforce the MFA rules in your application's database, APIs, and server-side rendering. Depending on your application's needs, there are three ways you can choose to enforce MFA. 1. **Enforce for all users (new and existing).** Any user account will have to enroll MFA to continue using your app. The application will not allow access without going through MFA first. 2. **Enforce for new users only.** Only new users will be forced to enroll MFA, while old users will be encouraged to do so. The application will not allow access for new users without going through MFA first. 3. **Enforce only for users that have opted-in.** Users that want MFA can enroll in it and the application will not allow access without going through MFA first. #### Example: React Below is an example that creates a new `UnenrollMFA` component that illustrates the important pieces of the MFA enrollment flow. Note that users can only unenroll a factor after completing the enrollment flow and obtaining an `aal2` JWT claim. Here are some points of note: * When the component appears on screen, the `supabase.auth.mfa.listFactors()` endpoint fetches all existing factors together with their details. * The existing factors for a user are displayed in a table. * Once the user has selected a factor to unenroll, they can type in the `factorId` and click **Unenroll** which creates a confirmation modal. ```tsx /** * UnenrollMFA shows a simple table with the list of factors together with a button to unenroll. * When a user types in the factorId of the factor that they wish to unenroll and clicks unenroll * the corresponding factor will be unenrolled. */ export function UnenrollMFA() { const [factorId, setFactorId] = useState('') const [factors, setFactors] = useState([]) const [error, setError] = useState('') // holds an error message useEffect(() => { ;(async () => { const { data, error } = await supabase.auth.mfa.listFactors() if (error) { throw error } setFactors([...data.totp, ...data.phone]) })() }, []) return ( <> {error &&
{error}
} Factor ID Friendly Name Factor Status Phone Number {factors.map((factor) => ( {factor.id} {factor.friendly_name} {factor.factor_type} {factor.status} {factor.phone} ))} setFactorId(e.target.value.trim())} /> ) } ``` #### Database Your app should sufficiently deny or allow access to tables or rows based on the user's current and possible authenticator levels. ##### Enforce for all users (new and existing) If your app falls under this case, this is a template Row Level Security policy you can apply to all your tables: ```sql create policy "Policy name." on table_name as restrictive to authenticated using ((select auth.jwt()->>'aal') = 'aal2'); ``` * Here the policy will not accept any JWTs with an `aal` claim other than `aal2`, which is the highest authenticator assurance level. * **Using `as restrictive` ensures this policy will restrict all commands on the table regardless of other policies!** ##### Enforce for new users only If your app falls under this case, the rules get more complex. User accounts created past a certain timestamp must have a `aal2` level to access the database. ```sql create policy "Policy name." on table_name as restrictive -- very important! to authenticated using (array[(select auth.jwt()->>'aal')] <@ ( select case when created_at >= '2022-12-12T00:00:00Z' then array['aal2'] else array['aal1', 'aal2'] end as aal from auth.users where (select auth.uid()) = id)); ``` * The policy will accept both `aal1` and `aal2` for users with a `created_at` timestamp prior to 12th December 2022 at 00:00 UTC, but will only accept `aal2` for all other timestamps. * The `<@` operator is PostgreSQL's ["contained in" operator.](https://www.postgresql.org/docs/current/functions-array.html) * **Using `as restrictive` ensures this policy will restrict all commands on the table regardless of other policies!** ##### Enforce only for users that have opted-in Users that have enrolled MFA on their account are expecting that your application only works for them if they've gone through MFA. ```sql create policy "Policy name." on table_name as restrictive -- very important! to authenticated using ( array[(select auth.jwt()->>'aal')] <@ ( select case when count(id) > 0 then array['aal2'] else array['aal1', 'aal2'] end as aal from auth.mfa_factors where ((select auth.uid()) = user_id) and status = 'verified' )); ``` * The policy will only accept only `aal2` when the user has at least one MFA factor verified. * Otherwise, it will accept both `aal1` and `aal2`. * The `<@` operator is PostgreSQL's ["contained in" operator.](https://www.postgresql.org/docs/current/functions-array.html) * **Using `as restrictive` ensures this policy will restrict all commands on the table regardless of other policies!** ### Server-Side Rendering It is possible to enforce MFA on the Server-Side Rendering level. However, this can be tricky do to well. You can use the `supabase.auth.mfa.getAuthenticatorAssuranceLevel()` and `supabase.auth.mfa.listFactors()` APIs to identify the AAL level of the session and any factors that are enabled for a user, similar to how you would use these on the browser. However, encountering a different AAL level on the server may not actually be a security problem. Consider these likely scenarios: 1. User signed-in with a conventional method but closed their tab on the MFA flow. 2. User forgot a tab open for a very long time. (This happens more often than you might imagine.) 3. User has lost their authenticator device and is confused about the next steps. We thus recommend you redirect users to a page where they can authenticate using their additional factor, instead of rendering a HTTP 401 Unauthorized or HTTP 403 Forbidden content. ### APIs If your application uses the Supabase Database, Storage or Edge Functions, just using Row Level Security policies will give you sufficient protection. In the event that you have other APIs that you wish to protect, follow these general guidelines: 1. **Use a good JWT verification and parsing library for your language.** This will let you securely parse JWTs and extract their claims. 2. **Retrieve the `aal` claim from the JWT and compare its value according to your needs.** If you've encountered an AAL level that can be increased, ask the user to continue the login process instead of logging them out. 3. **Use the `https://.supabase.co/rest/v1/auth/factors` REST endpoint to identify if the user has enrolled any MFA factors.** Only `verified` factors should be acted upon. ## Frequently asked questions # Multi-Factor Authentication (Phone) ## How does phone multi-factor-authentication work? Phone multi-factor authentication involves a shared code generated by Supabase Auth and the end user. The code is delivered via a messaging channel, such as SMS or WhatsApp, and the user uses the code to authenticate to Supabase Auth. The phone messaging configuration for MFA is shared with [phone auth login](/docs/guides/auth/phone-login). The same provider configuration that is used for phone login is used for MFA. You can also use the [Send SMS Hook](/docs/guides/auth/auth-hooks/send-sms-hook) if you need to use an MFA (Phone) messaging provider different from what is supported natively. Below is a flow chart illustrating how the Enrollment and Verify APIs work in the context of MFA (Phone). ### Add enrollment flow An enrollment flow provides a UI for users to set up additional authentication factors. Most applications add the enrollment flow in two places within their app: 1. Right after login or sign up. This allows users quickly set up Multi Factor Authentication (MFA) post login or account creation. Where possible, encourage all users to set up MFA. Many applications offer this as an opt-in step in an effort to reduce onboarding friction. 2. From within a settings page. Allows users to set up, disable or modify their MFA settings. As far as possible, maintain a generic flow that you can reuse in both cases with minor modifications. Enrolling a factor for use with MFA takes three steps for phone MFA: 1. Call `supabase.auth.mfa.enroll()`. 2. Calling the `supabase.auth.mfa.challenge()` API. This sends a code via SMS or WhatsApp and prepares Supabase Auth to accept a verification code from the user. 3. Calling the `supabase.auth.mfa.verify()` API. `supabase.auth.mfa.challenge()` returns a challenge ID. This verifies that the code issued by Supabase Auth matches the code input by the user. If the verification succeeds, the factor immediately becomes active for the user account. If not, you should repeat steps 2 and 3. #### Example: React Below is an example that creates a new `EnrollMFA` component that illustrates the important pieces of the MFA enrollment flow. * When the component appears on screen, the `supabase.auth.mfa.enroll()` API is called once to start the process of enrolling a new factor for the current user. * A challenge is created using the `supabase.auth.mfa.challenge()` API and the code from the user is submitted for verification using the `supabase.auth.mfa.verify()` challenge. * `onEnabled` is a callback that notifies the other components that enrollment has completed. * `onCancelled` is a callback that notifies the other components that the user has clicked the `Cancel` button. ```tsx export function EnrollMFA({ onEnrolled, onCancelled, }: { onEnrolled: () => void onCancelled: () => void }) { const [phoneNumber, setPhoneNumber] = useState('') const [factorId, setFactorId] = useState('') const [verifyCode, setVerifyCode] = useState('') const [error, setError] = useState('') const [challengeId, setChallengeId] = useState('') const onEnableClicked = () => { setError('') ;(async () => { const verify = await auth.mfa.verify({ factorId, challengeId, code: verifyCode, }) if (verify.error) { setError(verify.error.message) throw verify.error } onEnrolled() })() } const onEnrollClicked = async () => { setError('') try { const factor = await auth.mfa.enroll({ phone: phoneNumber, factorType: 'phone', }) if (factor.error) { setError(factor.error.message) throw factor.error } setFactorId(factor.data.id) } catch (error) { setError('Failed to Enroll the Factor.') } } const onSendOTPClicked = async () => { setError('') try { const challenge = await auth.mfa.challenge({ factorId }) if (challenge.error) { setError(challenge.error.message) throw challenge.error } setChallengeId(challenge.data.id) } catch (error) { setError('Failed to resend the code.') } } return ( <> {error &&
{error}
} setPhoneNumber(e.target.value.trim())} /> setVerifyCode(e.target.value.trim())} /> ) } ``` ### Add a challenge step to login Once a user has logged in via their first factor (email+password, magic link, one time password, social login etc.) you need to perform a check if any additional factors need to be verified. This can be done by using the `supabase.auth.mfa.getAuthenticatorAssuranceLevel()` API. When the user signs in and is redirected back to your app, you should call this method to extract the user's current and next authenticator assurance level (AAL). Therefore if you receive a `currentLevel` which is `aal1` but a `nextLevel` of `aal2`, the user should be given the option to go through MFA. Below is a table that explains the combined meaning. | Current Level | Next Level | Meaning | | ------------: | :--------- | :------------------------------------------------------- | | `aal1` | `aal1` | User does not have MFA enrolled. | | `aal1` | `aal2` | User has an MFA factor enrolled but has not verified it. | | `aal2` | `aal2` | User has verified their MFA factor. | | `aal2` | `aal1` | User has disabled their MFA factor. (Stale JWT.) | #### Example: React Adding the challenge step to login depends heavily on the architecture of your app. However, a fairly common way to structure React apps is to have a large component (often named `App`) which contains most of the authenticated application logic. This example will wrap this component with logic that will show an MFA challenge screen if necessary, before showing the full application. This is illustrated in the `AppWithMFA` example below. ```tsx function AppWithMFA() { const [readyToShow, setReadyToShow] = useState(false) const [showMFAScreen, setShowMFAScreen] = useState(false) useEffect(() => { ;(async () => { try { const { data, error } = await supabase.auth.mfa.getAuthenticatorAssuranceLevel() if (error) { throw error } console.log(data) if (data.nextLevel === 'aal2' && data.nextLevel !== data.currentLevel) { setShowMFAScreen(true) } } finally { setReadyToShow(true) } })() }, []) if (readyToShow) { if (showMFAScreen) { return } return } return <> } ``` * `supabase.auth.mfa.getAuthenticatorAssuranceLevel()` does return a promise. Don't worry, this is a very fast method (microseconds) as it rarely uses the network. * `readyToShow` only makes sure the AAL check completes before showing any application UI to the user. * If the current level can be upgraded to the next one, the MFA screen is shown. * Once the challenge is successful, the `App` component is finally rendered on screen. Below is the component that implements the challenge and verify logic. ```tsx function AuthMFA() { const [verifyCode, setVerifyCode] = useState('') const [error, setError] = useState('') const [factorId, setFactorId] = useState('') const [challengeId, setChallengeId] = useState('') const [phoneNumber, setPhoneNumber] = useState('') const startChallenge = async () => { setError('') try { const factors = await supabase.auth.mfa.listFactors() if (factors.error) { throw factors.error } const phoneFactor = factors.data.phone[0] if (!phoneFactor) { throw new Error('No phone factors found!') } const factorId = phoneFactor.id setFactorId(factorId) setPhoneNumber(phoneFactor.phone) const challenge = await supabase.auth.mfa.challenge({ factorId }) if (challenge.error) { setError(challenge.error.message) throw challenge.error } setChallengeId(challenge.data.id) } catch (error) { setError(error.message) } } const verifyCode = async () => { setError('') try { const verify = await supabase.auth.mfa.verify({ factorId, challengeId, code: verifyCode, }) if (verify.error) { setError(verify.error.message) throw verify.error } } catch (error) { setError(error.message) } } return ( <>
Please enter the code sent to your phone.
{phoneNumber &&
Phone number: {phoneNumber}
} {error &&
{error}
} setVerifyCode(e.target.value.trim())} /> {!challengeId ? ( ) : ( )} ) } ``` * You can extract the available MFA factors for the user by calling `supabase.auth.mfa.listFactors()`. Don't worry this method is also very quick and rarely uses the network. * If `listFactors()` returns more than one factor (or of a different type) you should present the user with a choice. For simplicity this is not shown in the example. * Phone numbers are unique per user. Users can only have one verified phone factor with a given phone number. Attempting to enroll a new phone factor alongside an existing verified factor with the same number will result in an error. * Each time the user presses the "Submit" button a new challenge is created for the chosen factor (in this case the first one) * On successful verification, the client library will refresh the session in the background automatically and finally call the `onSuccess` callback, which will show the authenticated `App` component on screen. ### Security configuration Each code is valid for up to 5 minutes, after which a new one can be sent. Successive codes remain valid until expiry. When possible choose the longest code length acceptable to your use case, at a minimum of 6. This can be configured in the [Authentication Settings](/dashboard/project/_/settings/auth). Be aware that Phone MFA is vulnerable to SIM swap attacks where an attacker will call a mobile provider and ask to port the target's phone number to a new SIM card and then use the said SIM card to intercept an MFA code. Evaluate the your application's tolerance for such an attack. You can read more about SIM swapping attacks [here](https://en.wikipedia.org/wiki/SIM_swap_scam) ## Pricing For a detailed breakdown of how charges are calculated, refer to [Manage Advanced MFA Phone usage](/docs/guides/platform/manage-your-usage/advanced-mfa-phone). # Multi-Factor Authentication (TOTP) ## How does app authenticator multi-factor authentication work? App Authenticator (TOTP) multi-factor authentication involves a timed one-time password generated from an authenticator app in the control of users. It uses a QR Code which to transmit a shared secret used to generate a One Time Password. A user can scan a QR code with their phone to capture a shared secret required for subsequent authentication. The use of a QR code was [initially introduced by Google Authenticator](https://github.com/google/google-authenticator/wiki/Key-Uri-Format) but is now universally accepted by all authenticator apps. The QR code has an alternate representation in URI form following the `otpauth` scheme such as: `otpauth://totp/supabase:alice@supabase.com?secret=&issuer=supabase` which a user can manually input in cases where there is difficulty rendering a QR Code. Below is a flow chart illustrating how the Enrollment, Challenge, and Verify APIs work in the context of MFA (TOTP). [TOTP MFA API](/docs/reference/javascript/auth-mfa-api) is free to use and is enabled on all Supabase projects by default. ### Add enrollment flow An enrollment flow provides a UI for users to set up additional authentication factors. Most applications add the enrollment flow in two places within their app: 1. Right after login or sign up. This lets users quickly set up MFA immediately after they log in or create an account. We recommend encouraging all users to set up MFA if that makes sense for your application. Many applications offer this as an opt-in step in an effort to reduce onboarding friction. 2. From within a settings page. Allows users to set up, disable or modify their MFA settings. Enrolling a factor for use with MFA takes three steps: 1. Call `supabase.auth.mfa.enroll()`. This method returns a QR code and a secret. Display the QR code to the user and ask them to scan it with their authenticator application. If they are unable to scan the QR code, show the secret in plain text which they can type or paste into their authenticator app. 2. Calling the `supabase.auth.mfa.challenge()` API. This prepares Supabase Auth to accept a verification code from the user and returns a challenge ID. In the case of Phone MFA this step also sends the verification code to the user. 3. Calling the `supabase.auth.mfa.verify()` API. This verifies that the user has indeed added the secret from step (1) into their app and is working correctly. If the verification succeeds, the factor immediately becomes active for the user account. If not, you should repeat steps 2 and 3. #### Example: React Below is an example that creates a new `EnrollMFA` component that illustrates the important pieces of the MFA enrollment flow. * When the component appears on screen, the `supabase.auth.mfa.enroll()` API is called once to start the process of enrolling a new factor for the current user. * This API returns a QR code in the SVG format, which is shown on screen using a normal `` tag by encoding the SVG as a data URL. * Once the user has scanned the QR code with their authenticator app, they should enter the verification code within the `verifyCode` input field and click on `Enable`. * A challenge is created using the `supabase.auth.mfa.challenge()` API and the code from the user is submitted for verification using the `supabase.auth.mfa.verify()` challenge. * `onEnabled` is a callback that notifies the other components that enrollment has completed. * `onCancelled` is a callback that notifies the other components that the user has clicked the `Cancel` button. ```tsx /** * EnrollMFA shows a simple enrollment dialog. When shown on screen it calls * the `enroll` API. Each time a user clicks the Enable button it calls the * `challenge` and `verify` APIs to check if the code provided by the user is * valid. * When enrollment is successful, it calls `onEnrolled`. When the user clicks * Cancel the `onCancelled` callback is called. */ export function EnrollMFA({ onEnrolled, onCancelled, }: { onEnrolled: () => void onCancelled: () => void }) { const [factorId, setFactorId] = useState('') const [qr, setQR] = useState('') // holds the QR code image SVG const [verifyCode, setVerifyCode] = useState('') // contains the code entered by the user const [error, setError] = useState('') // holds an error message const onEnableClicked = () => { setError('') ;(async () => { const challenge = await supabase.auth.mfa.challenge({ factorId }) if (challenge.error) { setError(challenge.error.message) throw challenge.error } const challengeId = challenge.data.id const verify = await supabase.auth.mfa.verify({ factorId, challengeId, code: verifyCode, }) if (verify.error) { setError(verify.error.message) throw verify.error } onEnrolled() })() } useEffect(() => { ;(async () => { const { data, error } = await supabase.auth.mfa.enroll({ factorType: 'totp', }) if (error) { throw error } setFactorId(data.id) // Supabase Auth returns an SVG QR code which you can convert into a data // URL that you can place in an tag. setQR(data.totp.qr_code) })() }, []) return ( <> {error &&
{error}
} setVerifyCode(e.target.value.trim())} /> ) } ``` ### Add a challenge step to login Once a user has logged in via their first factor (email+password, magic link, one time password, social login etc.) you need to perform a check if any additional factors need to be verified. This can be done by using the `supabase.auth.mfa.getAuthenticatorAssuranceLevel()` API. When the user signs in and is redirected back to your app, you should call this method to extract the user's current and next authenticator assurance level (AAL). Therefore if you receive a `currentLevel` which is `aal1` but a `nextLevel` of `aal2`, the user should be given the option to go through MFA. Below is a table that explains the combined meaning. | Current Level | Next Level | Meaning | | ------------: | :--------- | :------------------------------------------------------- | | `aal1` | `aal1` | User does not have MFA enrolled. | | `aal1` | `aal2` | User has an MFA factor enrolled but has not verified it. | | `aal2` | `aal2` | User has verified their MFA factor. | | `aal2` | `aal1` | User has disabled their MFA factor. (Stale JWT.) | #### Example: React Adding the challenge step to login depends heavily on the architecture of your app. However, a fairly common way to structure React apps is to have a large component (often named `App`) which contains most of the authenticated application logic. This example will wrap this component with logic that will show an MFA challenge screen if necessary, before showing the full application. This is illustrated in the `AppWithMFA` example below. ```tsx function AppWithMFA() { const [readyToShow, setReadyToShow] = useState(false) const [showMFAScreen, setShowMFAScreen] = useState(false) useEffect(() => { ;(async () => { try { const { data, error } = await supabase.auth.mfa.getAuthenticatorAssuranceLevel() if (error) { throw error } console.log(data) if (data.nextLevel === 'aal2' && data.nextLevel !== data.currentLevel) { setShowMFAScreen(true) } } finally { setReadyToShow(true) } })() }, []) if (readyToShow) { if (showMFAScreen) { return } return } return <> } ``` * `supabase.auth.mfa.getAuthenticatorAssuranceLevel()` does return a promise. Don't worry, this is a very fast method (microseconds) as it rarely uses the network. * `readyToShow` only makes sure the AAL check completes before showing any application UI to the user. * If the current level can be upgraded to the next one, the MFA screen is shown. * Once the challenge is successful, the `App` component is finally rendered on screen. Below is the component that implements the challenge and verify logic. ```tsx function AuthMFA() { const [verifyCode, setVerifyCode] = useState('') const [error, setError] = useState('') const onSubmitClicked = () => { setError('') ;(async () => { const factors = await supabase.auth.mfa.listFactors() if (factors.error) { throw factors.error } const totpFactor = factors.data.totp[0] if (!totpFactor) { throw new Error('No TOTP factors found!') } const factorId = totpFactor.id const challenge = await supabase.auth.mfa.challenge({ factorId }) if (challenge.error) { setError(challenge.error.message) throw challenge.error } const challengeId = challenge.data.id const verify = await supabase.auth.mfa.verify({ factorId, challengeId, code: verifyCode, }) if (verify.error) { setError(verify.error.message) throw verify.error } })() } return ( <>
Please enter the code from your authenticator app.
{error &&
{error}
} setVerifyCode(e.target.value.trim())} /> ) } ``` * You can extract the available MFA factors for the user by calling `supabase.auth.mfa.listFactors()`. Don't worry this method is also very quick and rarely uses the network. * If `listFactors()` returns more than one factor (or of a different type) you should present the user with a choice. For simplicity this is not shown in the example. * Each time the user presses the "Submit" button a new challenge is created for the chosen factor (in this case the first one) and it is immediately verified. Any errors are displayed to the user. * On successful verification, the client library will refresh the session in the background automatically and finally call the `onSuccess` callback, which will show the authenticated `App` component on screen. ## Frequently asked questions # Send emails with custom SMTP If you're using Supabase Auth with the following configuration: * Email and password accounts * Passwordless accounts using one-time passwords or links sent over email (OTP, magic link, invites) * Email-based user invitations from the [Users page](/dashboard/project/_/auth/users) or from the Auth admin APIs * Social login with email confirmation You will need to set up a custom SMTP server to handle the delivery of messages to your users. To get you started and let you explore and set up email message templates for your application, Supabase provides a simple SMTP server for all projects. This server imposes a few important restrictions and is not meant for production use. **Send messages only to pre-authorized addresses.** Unless you configure a custom SMTP server for your project, Supabase Auth will refuse to deliver messages to addresses that are not part of the project's team. You can manage this in the [Team tab](/dashboard/org/_/team) of the organization's settings. For example, if your project's organization has these member accounts `person-a@example.com`, `person-b@example.com` and `person-c@example.com` then Supabase Auth will only send messages to these addresses. All other addresses will fail with the error message *Email address not authorized.* **Significant rate-limits that can change over time.** To maintain the health and reputation of the default SMTP sending service, the number of messages your project can send is limited and can change without notice. Currently this value is set to messages per hour. **No SLA guarantee on message delivery or uptime for the default SMTP service.** The default SMTP service is provided as best-effort only and intended for the following non-production use cases: * Exploring and getting started with Supabase Auth * Setting up and testing email templates with the members of the project's team * Building toy projects, demos or any non-mission-critical application We urge all customers to set up custom SMTP server for all other use cases. ## How to set up a custom SMTP server? Supabase Auth works with any email sending service that supports the SMTP protocol. First you will need to choose a service, create an account (if you already do not have one) and obtain the SMTP server settings and credentials for your account. These include: the SMTP server host, port, user and password. You will also need to choose a default From address, usually something like `no-reply@example.com`. A non-exhaustive list of services that work with Supabase Auth is: * [Resend](https://resend.com/docs/send-with-supabase-smtp) * [AWS SES](https://docs.aws.amazon.com/ses/latest/dg/send-email-smtp.html) * [Postmark](https://postmarkapp.com/developer/user-guide/send-email-with-smtp) * [Twilio SendGrid](https://www.twilio.com/docs/sendgrid/for-developers/sending-email/getting-started-smtp) * [ZeptoMail](https://www.zoho.com/zeptomail/help/smtp-home.html) * [Brevo](https://help.brevo.com/hc/en-us/articles/7924908994450-Send-transactional-emails-using-Brevo-SMTP) Once you've set up your account with an email sending service, head to the [Authentication settings page](/dashboard/project/_/settings/auth) to enable and configure custom SMTP. Once you save these settings, your project's Auth server will send messages to all addresses. To protect the reputation of your newly set up service a low rate-limit of 30 messages per hour is imposed. To adjust this to an acceptable value for your use case head to the [Rate Limits configuration page](/dashboard/project/_/auth/rate-limits). ## Dealing with abuse: How to maintain the sending reputation of your SMTP server? As you make your application known to the public and it grows in popularity, you can expect to see a few types of abuse that can negatively impact the reputation of your sending domain. A common source of abuse is bots or attackers signing up users to your application. They use lists of known email addresses to sign up users to your project with pre-determined passwords. These can vary in scale and intensity: sometimes the bots slowly send sign up requests over many months, or they send a lot of requests at once. Usually the goal for this behavior is: * To negatively affect your email sending reputation, after which they might ask for a ransom promising to stop the behavior. * To cause a short-term or even long-term Denial of Service attack on your service, by preventing new account creation, signins with magic links or one-time passwords, or to severely impact important security flows in your application (such as reset password or forgot password). * To force you to reduce the security posture of your project, such as by disabling email confirmations. At that point, they may target specific or a broad number of users by creating an account in their name. Then they can use social engineering techniques to trick them to use your application in such a way that both attacker and victim have access to the same account. Mitigation strategies: * [Configure CAPTCHA protection](/docs/guides/auth/auth-captcha) for your project, which is the most effective way to control bots in this scenario. You can use CAPTCHA services which provide invisible challenges where real users won't be asked to solve puzzles most of the time. * Prefer social login (OAuth) or SSO with SAML instead of email-based authentication flows in your apps. * Prefer passwordless authentication (one-time password) as this limits the attacker's value to gain from this behavior. * Do not disable email confirmations under pressure. ### Additional best practices **Set up and maintain DKIM, DMARC and SPF configurations.** Work with your email sending service to configure [DKIM, DMARC and SPF](https://www.cloudflare.com/learning/email-security/dmarc-dkim-spf/) for your sending domain. This will significantly increase the deliverability of your messages. **Set up a custom domain.** Authentication messages often contain links to your project's Auth server. [Setting up a custom domain](/docs/guides/platform/custom-domains) will reduce the likelihood of your messages being picked up as spam due to another Supabase project's bad reputation. **Don't mix Auth emails with marketing emails.** Use separate services for Auth and marketing messages. If the reputation of one falls, it won't affect your whole application or operation. This includes: * Use a separate sending domain for authentication -- `auth.example.com` and a separate domain for marketing `marketing.example.com`. * Use a separate From address -- `no-reply@auth.example.com` vs `no-reply@marketing.example.com`. **Have another SMTP service set up on stand-by.** In case the primary SMTP service you're using is experiencing difficulty, or your account is under threat of being blocked due to spam, you have another service to quickly turn to. **Use consistent branding and focused content.** Make sure you've separated out authentication messages from marketing messages. * Don't include promotional content as part of authentication messages. * Avoid talking about what your application is inside authentication messages. This can be picked up by automated spam filters which will classify the message as marketing and increase its chances of being regarded as spam. This problem is especially apparent if your project is related to: Web3, Blockchain, AI, NFTs, Gambling, Pornography. * Avoid taglines or other short-form marketing material in authentication messages. * Reduce the number of links and call-to-actions in authentication messages. * Change the authentication messages templates infrequently. Prefer a single big change over multiple smaller changes. * Avoid A/B testing content in authentication messages. * Use a separate base template (HTML) from your marketing messages. * Avoid the use of email signatures in authentication messages. If you do, make sure the signatures are different in style and content from your marketing messages. * Use short and to-the-point subject lines. Avoid or reduce the number of emojis in subjects. * Reduce the number of images placed in authentication messages. * Avoid including user-provided data such as names, usernames, email addresses or salutations in authentication messages. If you do, make sure they are sanitized. **Prepare for large surges ahead of time.** If you are planning on having a large surge of users coming at a specific time, work with your email sending service to adjust the rate limits and their expectations accordingly. Most email sending services dislike spikes in the number of messages being sent, and this may affect your sending reputation. Consider implementing additional protections for such events: * Build a queuing or waitlist system instead of allowing direct sign-up, which will help you control the number of messages being sent from the email sending service. * Disable email-based sign ups for the event and use social login only. Alternatively you can deprioritize the email-based sign-up flows for the event by hiding them in the UI or making them harder to reach. **Use the Send Email Auth Hook for more control.** If you need more control over the sending process, instead of using a SMTP server you can use the [Send Email Auth Hook](/docs/guides/auth/auth-hooks/send-email-hook). This can be useful in advanced scenarios such as: * You want to use React or a different email templating engine. * You want to use an email sending service that does not provide an SMTP service, or the non-SMTP API is more powerful. * You want to queue up messages instead of sending them immediately, in an effort to smooth out spikes in email sending or do additional filtering (avoid repetitive messages). * You want to use multiple email sending services to increase reliability (if primary service is unavailable, use backup service automatically). * You want to use different email sending services based on the email address or user data (e.g. service A for users in the USA, service B for users in the EU, service C for users in China). * You want to add or include additional email headers in messages, for tracking or other reasons. * You want to add attachments to the messages (generally not recommended). * You want to add [S/MIME signatures](https://en.wikipedia.org/wiki/S/MIME) to messages. * You want to use an email server not open to the Internet, such as some corporate or government mail servers. **Increase the duration of user sessions.** Having short lived [user sessions](/docs/guides/auth/sessions) can be problematic for email sending, as it forces active users to sign-in frequently, increasing the number of messages needed to be sent. Consider increasing the maximum duration of user sessions. If you do see an unnecessary increase in logins without a clear cause, check your frontend application for bugs. If you are using a [SSR](/docs/guides/auth/server-side) framework on the frontend and are seeing an increased number of user logins without a clear cause, check your set up. Make sure to keep the `@supabase/ssr` package up to date and closely follow the guides we publish. Make sure that the middleware components of your SSR frontend works as intended and matches the guides we've published. Sometimes a misplaced `return` or conditional can cause early session termination. # Error Codes Learn about the Auth error codes and how to resolve them ## Auth error codes Supabase Auth can return various errors when using its API. This guide explains how to handle these errors effectively across different programming languages. ## Error types Supabase Auth errors are generally categorized into two main types: * API Errors: Originate from the Supabase Auth API. * Client Errors: Originate from the client library's state. Client errors differ by language so do refer to the appropriate section below: ## HTTP status codes Below are the most common HTTP status codes you might encounter, along with their meanings in the context of Supabase Auth: ### [403 Forbidden](https://developer.mozilla.org/en-US/docs/Web/HTTP/Status/403) Sent out in rare situations where a certain Auth feature is not available for the user, and you as the developer are not checking a precondition whether that API is available for the user. ### [422 Unprocessable Entity](https://developer.mozilla.org/en-US/docs/Web/HTTP/Status/422) Sent out when the API request is accepted, but cannot be processed because the user or Auth server is in a state where it cannot satisfy the request. ### [429 Too Many Requests](https://developer.mozilla.org/en-US/docs/Web/HTTP/Status/429) Sent out when rate-limits are breached for an API. You should handle this status code often, especially in functions that authenticate a user. ### [500 Internal Server Error](https://developer.mozilla.org/en-US/docs/Web/HTTP/Status/500) Indicate that the Auth server's service is degraded. Most often it points to issues in your database setup such as a misbehaving trigger on a schema, function, view or other database object. ### [501 Not Implemented](https://developer.mozilla.org/en-US/docs/Web/HTTP/Status/501) Sent out when a feature is not enabled on the Auth server, and you are trying to use an API which requires it. ## Auth error codes table The following table provides a comprehensive list of error codes you may encounter when working with Supabase Auth. Each error code is associated with a specific issue and includes a description to help you understand and resolve the problem efficiently. ## Best practices for error handling * Always use `error.code` and `error.name` to identify errors, not string matching on error messages. * Avoid relying solely on HTTP status codes, as they may change unexpectedly. # Enterprise Single Sign-On Supabase Auth supports building enterprise applications that require Single Sign-On (SSO) authentication [with SAML 2.0](/docs/guides/auth/sso/auth-sso-saml). # Single Sign-On with SAML 2.0 for Projects Supabase Auth supports enterprise-level Single Sign-On (SSO) for any identity providers compatible with the SAML 2.0 protocol. This is a non-exclusive list of supported identity providers: * Google Workspaces (formerly known as G Suite) * Okta, Auth0 * Microsoft Active Directory, Azure Active Directory, Microsoft Entra * PingIdentity * OneLogin If you're having issues with identity provider software not on this list, [open a support ticket](https://supabase.com/dashboard/support/new). ## Prerequisites This guide requires the use of the [Supabase CLI](/docs/guides/cli). Make sure you're using version v1.46.4 or higher. You can use `supabase -v` to see the currently installed version. You can use the `supabase sso` [subcommands](/docs/reference/cli/supabase-sso) to manage your project's configuration. SAML 2.0 support is disabled by default on Supabase projects. You can configure this on the [Auth Providers](https://supabase.com/dashboard/project/_/auth/providers) page on your project. Note that SAML 2.0 support is offered on plans Pro and above. Check the [Pricing](https://supabase.com/pricing) page for more information. ## Terminology The number of SAML and SSO acronyms can often be overwhelming. Here's a glossary which you can refer back to at any time: * **Identity Provider**, **IdP**, or **IDP** An identity provider is a service that manages user accounts at a company or organization. It can verify the identity of a user and exchange that information with your Supabase project and other applications. It acts as a single source of truth for user identities and access rights. Commonly used identity providers are: Microsoft Active Directory (Azure AD, Microsoft Entra), Okta, Google Workspaces (G Suite), PingIdentity, OneLogin, and many others. There are also self-hosted and on-prem versions of identity providers, and sometimes they are accessible only by having access to a company VPN or being in a specific building. * **Service Provider**, **SP** This is the software that is asking for user information from an identity provider. In Supabase, this is your project's Auth server. * **Assertion** An assertion is a statement issued by an identity provider that contains information about a user. * **`EntityID`** A globally unique ID (usually a URL) that identifies an Identity Provider or Service Provider across the world. * **`NameID`** A unique ID (usually an email address) that identifies a user at an Identity Provider. * **Metadata** An XML document that describes the features and configuration of an Identity Provider or Service Provider. It can be as a standalone document or as a URL. Usually (but not always) the `EntityID` is the URL at which you can access the Metadata. * **Certificate** Supabase Auth (the Service Provider) trusts assertions from an Identity Provider based on the signature attached to the assertion. The signature is verified according to the certificate present in the Metadata. * **Assertion Consumer Service (ACS) URL** This is one of the most important SAML URLs. It is the URL where Supabase Auth will accept assertions from an identity provider. Basically, once the identity provider verifies the user's identity it will redirect to this URL and the redirect request will contain the assertion. * **Binding (Redirect, POST, or Artifact)** This is a description of the way an identity provider communicates with Supabase Auth. When using the Redirect binding, the communication occurs using HTTP 301 redirects. When it's `POST`, it's using `POST` requests sent with `
` elements on a page. When using Artifact, it's using a more secure exchange over a Redirect or `POST`. * **`RelayState`** State used by Supabase Auth to hold information about a request to verify the identity of a user. ## Important SAML 2.0 information Below is information about your project's SAML 2.0 configuration which you can share with the company or organization that you're trying to on-board. | Name | Value | | --------------------------- | ----------------------------------------------------------------------- | | `EntityID` | `https://.supabase.co/auth/v1/sso/saml/metadata` | | Metadata URL | `https://.supabase.co/auth/v1/sso/saml/metadata` | | Metadata URL(download) | `https://.supabase.co/auth/v1/sso/saml/metadata?download=true` | | ACS URL | `https://.supabase.co/auth/v1/sso/saml/acs` | | SLO URL | `https://.supabase.co/auth/v1/sso/slo` | | `NameID` | Required `emailAddress` or `persistent` | Note that SLO (Single Logout) is not supported at this time with Supabase Auth as it is a rarely supported feature by identity providers. However, the URL is registered and advertised for when this does become available. SLO is a best-effort service, so we recommend considering [Session Timebox or Session Inactivity Timeout](/docs/guides/auth/sessions#limiting-session-lifetime-and-number-of-allowed-sessions-per-user) instead to force your end-users to authenticate regularly. Append `?download=true` to the Metadata URL to download the Metadata XML file. This is useful in cases where the identity provider requires a file. Alternatively, you can use the `supabase sso info --project-ref ` [command](/docs/reference/cli/supabase-sso-info) to get setup information for your project. ### User accounts and identities User accounts and identities created via SSO differ from regular (email, phone, password, social login...) accounts in these ways: * **No automatic linking.** Each user account verified using a SSO identity provider will not be automatically linked to existing user accounts in the system. That is, if a user `valid.email@supabase.io` had signed up with a password, and then uses their company SSO login with your project, there will be two `valid.email@supabase.io` user accounts in the system. * **Emails are not necessarily unique.** Given the behavior with no automatic linking, email addresses are no longer a unique identifier for a user account. Always use the user's UUID to correctly reference user accounts. * **Sessions may have a maximum duration.** Depending on the configuration of the identity provider, a login session established with SSO may forcibly log out a user after a certain period of time. ### Row Level Security You can use information about the SSO identity provider in Row Level Security policies. Here are some commonly used statements to extract SSO related information from the user's JWT: * `auth.jwt()#>>'{amr,0,method}'` Returns the name of the last method used to verify the identity of this user. With SAML SSO this is `sso/saml`. * `auth.jwt()#>>'{amr,0,provider}'` Returns the UUID of the SSO identity provider used by the user to sign-in. * `auth.jwt()#>>'{user_metadata,iss}'` Returns the identity provider's SAML 2.0 `EntityID` A common use case with SSO is to use the UUID of the identity provider as the identifier for the organization the user belongs to -- frequently known as a tenant. By associating the identity provider's UUID with your tenants, you can use restrictive RLS policies to scope down actions and data that a user is able to access. For example, let's say you have a table like: ```sql create table organization_settings ( -- the organization's unique ID id uuid not null primary key, -- the organization's SSO identity provider sso_provider_id uuid unique, -- name of the organization name text, -- billing plan (paid, Free, Enterprise) billing_plan text ); ``` You can use the information present in the user's JWT to scope down which rows from this table the user can see, without doing any additional user management: ```sql CREATE POLICY "View organization settings." ON organization_settings AS RESTRICTIVE USING ( sso_provider_id = (select auth.jwt()#>>'{amr,0,provider}') ); ``` ## Managing SAML 2.0 connections Once you've enabled SAML 2.0 support on your project via the [Auth Providers](https://supabase.com/dashboard/project/_/auth/providers) page in the dashboard, you can use the [Supabase CLI](/docs/reference/cli/supabase-sso) to add, update, remove and view information about identity providers. ### Add a connection To establish a connection to a SAML 2.0 Identity Provider (IdP) you will need: * A SAML 2.0 Metadata XML file, or a SAML 2.0 Metadata URL pointing to an XML file * (Optional) Email domains that the organization's IdP uses * (Optional) Attribute mappings between the user properties of the IdP and the claims stored by Supabase Auth You should obtain the SAML 2.0 Metadata XML file or URL from the organization whose IdP you wish to connect. Most SAML 2.0 Identity Providers support the Metadata URL standard, and we recommend using a URL if this is available. Commonly used SAML 2.0 Identity Providers that support Metadata URLs: * Okta * Azure AD (Microsoft Entra) * PingIdentity Commonly used SAML 2.0 Identity Providers that only support Metadata XML files: * Google Workspaces (G Suite) * Any self-hosted or on-prem identity provider behind a VPN Once you've obtained the SAML 2.0 Metadata XML file or URL you can [establish a connection](/docs/reference/cli/supabase-sso-add) with your project's Supabase Auth server by running: ```bash supabase sso add --type saml --project-ref \ --metadata-url 'https://company.com/idp/saml/metadata' \ --domains company.com ``` If you wish to use a Metadata XML file instead, you can use: ```bash supabase sso add --type saml --project-ref \ --metadata-file /path/to/saml/metadata.xml \ --domains company.com ``` This command will register a new identity provider with your project's Auth server. When successful, you will see the details of the provider such as it's SAML information and registered domains. Note that only persons with write access to the project can register, update or remove identity providers. Once you've added an identity provider, users who have access to it can sign in to your application. With SAML 2.0 there are two ways that users can sign in to your project: * By signing-in from your application's user interface, commonly known as **SP (Service Provider) Initiated Flow** * By clicking on an icon in the application menu on the company intranet or identity provider page, commonly known as **Identity Provider Initiated (IdP) Flow** To initiate a sign-in request from your application's user interface (i.e. the SP Initiated Flow), you can use: ### Understanding attribute mappings When a user signs in using the SAML 2.0 Single Sign-On protocol, an XML document called the SAML Assertion is exchanged between the identity provider and Supabase Auth. This assertion contains information about the user's identity and other authentication information, such as: * Unique ID of the user (called `NameID` in SAML) * Email address * Name of the user * Department or organization * Other attributes present in the users directory managed by the identity provider With exception of the unique user ID, SAML does not require any other attributes in the assertion. Identity providers can be configured so that only select user information is shared with your project. Your project can be configured to recognize these attributes and map them into your project's database using a JSON structure. This process is called attribute mapping, and varies according to the configuration of the identity provider. For example, the following JSON structure configures attribute mapping for the `email` and `first_name` user identity properties. ```json { "keys": { "email": { "name": "mail" }, "first_name": { "name": "givenName" } } } ``` When creating or updating an identity provider with the [Supabase CLI](/docs/guides/cli) you can include this JSON as a file with the `--attribute-mapping-file /path/to/attribute/mapping.json` flag. For example, to change the attribute mappings to an existing provider you can use: ```bash supabase sso update --project-ref \ --attribute-mapping-file /path/to/attribute/mapping.json ``` Given a SAML 2.0 assertion that includes these attributes: ```xml valid.email@supabase.io Jane Doe ``` Will result in the following claims in the user's identity in the database and JWT: ```json { "email": "valid.email@supabase.io", "custom_claims": { "first_name": "Jane Doe" } } ``` Supabase Auth does not require specifying attribute mappings if you only need access to the user's email. It will attempt to find an email attribute specified in the assertion. All other properties will not be automatically included, and it is those you need to map. At this time it is not possible to have users without an email address, so SAML assertions without one will be rejected. Most SAML 2.0 identity providers use Lightweight Directory Access Protocol (LDAP) attribute names. However, due to their variability and complexity operators of identity providers are able to customize both the `Name` and attribute value that is sent to Supabase Auth in an assertion. Refer to the identity provider's documentation and contact the operator for details on what attributes are mapped for your project. **Accessing the stored attributes** The stored attributes, once mapped, show up in the access token (a JWT) of the user. If you need to look these values up in the database, you can find them in the `auth.identities` table under the `identity_data` JSON column. Identities created for SSO providers have `sso:` in the `provider` column, while `id` contains the unique `NameID` of the user account. Furthermore, you can find the same identity data under `raw_app_meta_data` inside `auth.users`. ### Remove a connection Once a connection to an identity provider is established, you can [remove it](/docs/reference/cli/supabase-sso-remove) by running: ```bash supabase sso remove --project-ref ``` If successful, the details of the removed identity provider will be shown. All user accounts from that identity provider will be immediately logged out. User information will remain in the system, but it will no longer be possible for any of those accounts to be accessed in the future, even if you add the connection again. If you need to reassign those user accounts to another identity provider, [open a support ticket](https://supabase.com/dashboard/support/new). A [list of all](/docs/reference/cli/supabase-sso-list) registered identity providers can be displayed by running: ```bash supabase sso list --project-ref ``` ### Update a connection You may wish to update settings about a connection to a SAML 2.0 identity provider. Commonly this is necessary when: * Cryptographic keys are rotated or have expired * Metadata URL has changed, but is the same identity provider * Other SAML 2.0 Metadata attributes have changed, but it is still the same identity provider * You are updating the domains or attribute mapping You can use this command to [update](/docs/reference/cli/supabase-sso-update) the configuration of an identity provider: ```bash supabase sso update --project-ref ``` Use `--help` to see all available flags. It is not possible to change the unique SAML identifier of the identity provider, known as `EntityID`. Everything else can be updated. If the SAML `EntityID` of your identity provider has changed, it is regarded as a new identity provider and you will have to register it like a new connection. ### Retrieving information about a connection You can always obtain a [list](/docs/reference/cli/supabase-sso-list) of all registered providers using: ```bash supabase sso list --project-ref ``` This list will only include basic information about each provider. To see [all of the information](/docs/reference/cli/supabase-sso-show) about a provider you can use: ```bash supabase sso show --project-ref ``` You can use the `-o json` flag to output the information as JSON, should you need to. Other formats may be supported, use `--help` to see all available options. ## Pricing For a detailed breakdown of how charges are calculated, refer to [Manage Monthly Active SSO Users usage](/docs/guides/platform/manage-your-usage/monthly-active-users-sso). ## Frequently asked questions ### Publishing your application to an identity provider's marketplace Many cloud-based identity providers offer a marketplace where you can register your application for easy on-boarding with customers. When you use Supabase Auth's SAML 2.0 support you can register your project in any one of these marketplaces. Refer to the relevant documentation for each cloud-based identity provider on how you can do this. Some common marketplaces are: * [Okta Integration Network](https://developer.okta.com/docs/guides/build-sso-integration/saml2/main/) * [Azure Active Directory App Gallery](https://learn.microsoft.com/en-us/azure/active-directory-b2c/publish-app-to-azure-ad-app-gallery) * [Google Workspaces Pre-integrated SAML apps catalog](https://support.google.com/a/table/9217027) ### Why do some users get: SAML assertion does not contain email address? Identity providers do not have to send back and email address for the user, though they often do. Supabase Auth requires that an email address is present. The following list of commonly used SAML attribute names is inspected, in order of appearance, to discover the email address in the assertion: * `urn:oid:0.9.2342.19200300.100.1.3` * `http://schemas.xmlsoap.org/ws/2005/05/identity/claims/emailaddress` * `http://schemas.xmlsoap.org/claims/EmailAddress` * `mail` * `email` Finally if there is no such attribute, it will use the SAML `NameID` value but only if the format is advertised as `urn:oasis:names:tc:SAML:1.1:nameid-format:emailAddress`. Should you run into this problem, it is most likely a misconfiguration issue **on the identity provider side.** Instruct your contact at the company to map the user's email address to one of the above listed attribute names, typically `email`. ### Accessing the private key used for SAML in your project At this time it is not possible to extract the RSA private key used by your project's Supabase Auth server. This is done to keep the private key as secure as possible, given that SAML does not offer an easy way to rotate keys without disrupting service. (Use a SAML 2.0 Metadata URL whenever possible for this reason!) If you really need access to the key, [open a support ticket](https://supabase.com/dashboard/support/new) and we'll try to support you as best as possible. ### Is multi-tenant SSO with SAML supported? Yes, Supabase supports multi-tenant Single Sign-On (SSO) using SAML 2.0. While the dashboard displays only one SAML field, you can set up multiple SAML connections using the Supabase CLI. Each connection is assigned a unique `sso_provider_id`, which is included in the user's JWT and can be used in Row Level Security (RLS) policies. You can configure custom attribute mappings for each connection to include tenant-specific information, such as roles. This setup allows you to implement multi-tenant SSO for multiple clients or organizations within a single application. For example, if you have an app with multiple clients using different Azure Active Directories, you can create separate SAML connections for each and use the `sso_provider_id` to manage access and apply appropriate security policies. ### Is multi-subdomain SSO with SAML supported? Yes, also referred to as [cross-origin authentication within the same site](https://web.dev/articles/same-site-same-origin). To redirect to a URL other than the [Site URL](https://supabase.com/docs/guides/auth/redirect-urls), following the SAML response from the IdP, the `redirectTo` option can be added to [`signInWithSSO`](https://supabase.com/docs/reference/javascript/auth-signinwithsso). ```ts import { createClient } from '@supabase/supabase-js' const supabase = createClient('https://your-project.supabase.co', 'your-anon-key') // ---cut--- const { data, error } = await supabase.auth.signInWithSSO({ domain: 'company.com', options: { redirectTo: `https://app.company.com/callback`, }, }) ``` When redirecting to a URL other than the Site URL, a `/callback` endpoint is necessary to process the auth code from the IdP and exchange it for a session. This assumes the [Supabase SSR client](https://supabase.com/docs/guides/auth/server-side/creating-a-client) has already been configured. # General configuration General configuration options for Supabase Auth This section covers the [general configuration options](/dashboard/project/_/settings/auth) for Supabase Auth. If you are looking for another type of configuration, you may be interested in one of the following sections: * [Provider-specific configuration](/dashboard/project/_/auth/providers) * [Rate limits](/dashboard/project/_/auth/rate-limits) * [Email Templates](/dashboard/project/_/auth/templates) * [Redirect URLs](/dashboard/project/_/auth/url-configuration) * [Auth Hooks](/dashboard/project/_/auth/hooks) Supabase Auth provides these [general configuration options](/dashboard/project/_/settings/auth) to control user access to your application: * **Allow new users to sign up**: Users will be able to sign up. If this config is disabled, only existing users can sign in. * **Confirm Email**: Users will need to confirm their email address before signing in for the first time. * Having **Confirm Email** disabled assumes that the user's email does not need to be verified in order to login and implicitly confirms the user's email in the database. * This option can be found in the email provider under the provider-specific configuration. * **Allow anonymous sign-ins**: Allow anonymous users to be created. * **Allow manual linking**: Allow users to link their accounts manually. # Identities An identity is an authentication method associated with a user. Supabase Auth supports the following types of identity: * Email * Phone * OAuth * SAML A user can have more than one identity. Anonymous users have no identity until they link an identity to their user. ## The user identity object The user identity object contains the following attributes: | Attributes | Type | Description | | --------------- | -------- | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | provider\_id | `string` | The provider id returned by the provider. If the provider is an OAuth provider, the id refers to the user's account with the OAuth provider. If the provider is `email` or `phone`, the id is the user's id from the `auth.users` table. | | user\_id | `string` | The user's id that the identity is linked to. | | identity\_data | `object` | The identity metadata. For OAuth and SAML identities, this contains information about the user from the provider. | | id | `string` | The unique id of the identity. | | provider | `string` | The provider name. | | email | `string` | The email is a generated column that references the optional email property in the identity\_data | | created\_at | `string` | The timestamp that the identity was created. | | last\_sign\_in\_at | `string` | The timestamp that the identity was last used to sign in. | | updated\_at | `string` | The timestamp that the identity was last updated. | # JWTs JSON Web Tokens A [JSON Web Token](https://jwt.io/introduction) is a type of data structure, represented as a string, that usually contains identity and authorization information about a user. It encodes information about its lifetime and is signed with a cryptographic key to make it tamper-resistant. Supabase Access Tokens are JWTs. The JWT is sent along with every request to Supabase services. By verifying the token and inspecting the included claims, you can allow or deny access to resources. [Row Level Security](/docs/guides/database/postgres/row-level-security) policies are based on the information present in JWTs. ## Encoding and signing JWTs JWTs are encoded and signed as follows. The JSON object starts out looking something like this: ```js { "sub": "0001", "name": "Sam Vimes", "iat": 1516239022, "exp": 1518239022 } ``` `sub` is the "subject", which is usually the UUID of the user. `name` is self-explanatory, and `iat` is the Unix timestamp at which the token was created. Many JWTs will also have an `exp`, which is the date at which the token is set to expire and can no longer be used. These are some of the standard fields you may find in a JWT, but you can pretty much store whatever you want in there, for example: ```js { "sub": "0002", "name": "Věra Hrabánková", "iat": 1516239022, "exp": 1518239022, "theme": { "primary" : "#D80C14", "secondary" : "#FFFFFF" } } ``` Just note that the more data you store in your token, the longer the encoded string will be. When we want to send the JWT to the user, we first encode the data using an algorithm such as `HS256`. There are many libraries (and several different algorithms) that can be used to do this encoding/decoding, such as [`jsonwebtoken`](https://www.npmjs.com/package/jsonwebtoken). The signing is as simple as: ```js // from https://replit.com/@awalias/jsonwebtokens#index.js let token = jwt.sign({ name: 'Sam Vimes' }, 'some-secret') ``` And the resulting string will look like this: ```js eyJhbGciOiJIUzI1NiJ9 .eyJzdWIiOiIwMDAxIiwibmFtZSI6IlNhbSBWaW1lcyIsImlhdCI6MTUxNjIzOTAyMiwiZXhwIjoxNTE4MjM5MDIyfQ .zMcHjKlkGhuVsiPIkyAkB2rjXzyzJsMMgpvEGvGtjvA ``` You will notice that the string is actually made up of three components: The first segment `eyJhbGciOiJIUzI1NiJ9` is known as the "header", and when decoded just tells us which algorithm was used to do the encoding: ```js { "alg": "HS256" } ``` The second segment contains our original payload: ```js { "sub": "0001", "name": "Sam Vimes", "iat": 1516239022, "exp": 1518239022 } ``` The last segment `zMcHjKlkGhuVsiPIkyAkB2rjXzyzJsMMgpvEGvGtjvA` is the signature itself, which is the part used by the website or service provider to verify that a token sent by some user is legitimate. It is produced in the first instance by running the cryptographic function HS256 on the following input: ```js HMACSHA256( base64UrlEncode(header) + "." + base64UrlEncode(payload) ) ``` You can test out minting your own tokens on . It is important to note that anyone who possesses the `jwt_secret` here can create new tokens, and also verify existing ones. More advanced JWT algorithms use two secrets: one for the creation of tokens, and a separate one to verify the validity of signed tokens. You might wonder why JWTs are so popular all of a sudden. The answer is that with the mass adoption of microservice architecture, we were in a situation where several distinct microservices (APIs, websites, servers, etc.) want to validate that a user is who they say they are, or are in other words a "logged-in" user. Traditional session tokens are no use here, since they would require each microservice to either maintain a record of currently valid session tokens or to query a central database each time a user wants to access a resource in order to check the validity of the session token – very inefficient indeed. JWT-based auth in this sense is decentralized, since anyone with the `jwt_secret` can verify a token without needing access to a centralized database. Note: One downside of JWTs is that they are not easily voidable, unlike session tokens. If a JWT is leaked to a malicious actor, they will be able to redeem it anywhere until the expiry date is reached – unless of course the system owner updates the `jwt_secret` (which will of course invalidate *everyone's* existing tokens). ## JWTs in Supabase In Supabase we issue JWTs for three different purposes: 1. `anon key`: This key is used to bypass the Supabase API gateway and can be used in your client-side code. 2. `service role key`: This key has super admin rights and can bypass your Row Level Security. Do not put it in your client-side code. Keep it private. 3. `user specific jwts`: These are tokens we issue to users who log into your project/service/website. It's the modern equivalent of a session token, and can be used by a user to access content or permissions specific to them. The first token here, the `anon key` token, is for developers to send along with their API requests whenever they want to interact with their Supabase database. Let's say you want to read the names of all the rows in a table `colors`. We would make a request like: ```bash curl 'https://xscduanzzfseqszwzhcy.supabase.co/rest/v1/colors?select=name' \ -H "apikey: eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJyb2xlIjoiYW5vbiIsImlhdCI6MTYxNDIwNTE3NCwiZXhwIjoxOTI5NzgxMTc0fQ.-NBR1WnZyQGpRLdXJfgfpszoZ0EeE6KHatJsDPLIX8c" ``` If we put this token into https://jwt.io, we see it decodes to: ```js { "role": "anon", "iss": "supabase", "iat": 1614205174, "exp": 1929781174 } ``` This JWT is signed by a `jwt_secret` specific to the developer's Supabase token (you can find this secret alongside this encoded "anon key" on your Dashboard under Settings > API page) and is required to get past the Supabase API gateway and access the developer's project. The idea with this particular key is that it's safe to put into your client, meaning it's okay if your end users see this key – but *only* if you first enable Row Level Security. The second key, `service role key`, should only ever be used on one of your own servers or environments, and should never be shared with end users. You might use this token to do things like make batch inserts of data. The `user access token` is the JWT issued when you call for example: ```js supabase.auth.signIn({ email: 'valid.email@supabase.io', password: 'They_Live_1988!', }) ``` This token should be passed in addition to the `apikey` header as an `Authorization Bearer` header like: ```bash curl 'https://xscduanzzfseqszwzhcy.supabase.co/rest/v1/colors?select=name' \ -H "apikey: eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJyb2xlIjoiYW5vbiIsImlhdCI6MTYxNDIwNTE3NCwiZXhwIjoxOTI5NzgxMTc0fQ.-NBR1WnZyQGpRLdXJfgfpszoZ0EeE6KHatJsDPLIX8c" \ -H "Authorization: Bearer eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJhdWQiOiJhdXRoZW50aWNhdGVkIiwiZXhwIjoxNjE1ODI0Mzg4LCJzdWIiOiIwMzM0NzQ0YS1mMmEyLTRhYmEtOGM4YS02ZTc0OGY2MmExNzIiLCJlbWFpbCI6InNvbWVvbmVAZW1haWwuY29tIiwiYXBwX21ldGFkYXRhIjp7InByb3ZpZGVyIjoiZW1haWwifSwidXNlcl9tZXRhZGF0YSI6bnVsbCwicm9sZSI6ImF1dGhlbnRpY2F0ZWQifQ.I-_oSsJamtinGxniPETBf-ezAUwDW2sY9bJIThvdX9s" ``` You'll notice that this token is quite a bit longer, since it contains information specific to the user such as: ```js { "aud": "authenticated", "exp": 1615824388, "sub": "0334744a-f2a2-4aba-8c8a-6e748f62a172", "email": "valid.email@supabase.io", "app_metadata": { "provider": "email" }, "user_metadata": null, "role": "authenticated" } ``` If using the service role key, you'll need to pass it into both the `apikey` and `authorization` headers (again, only do this from a secure environment such as your own server): ```bash curl "$YOUR_PROJECT_URL/rest/v1/colors?select=name" \ -H "apikey: $YOUR_SERVICE_ROLE_KEY" \ -H "authorization: Bearer $YOUR_SERVICE_ROLE_KEY" ``` Now that you understand what JWTs are and where they're used in Supabase, you can explore how to use them in combination with Row Level Security to start restricting access to certain tables, rows, and columns in your Postgres database. ## Resources * JWT debugger: https://jwt.io/ # User Management View, delete, and export user information. You can view your users on the [Users page](/dashboard/project/_/auth/users) of the Dashboard. You can also view the contents of the Auth schema in the [Table Editor](/dashboard/project/_/editor). ## Accessing user data via API For security, the Auth schema is not exposed in the auto-generated API. If you want to access users data via the API, you can create your own user tables in the `public` schema. Make sure to protect the table by enabling [Row Level Security](/docs/guides/database/postgres/row-level-security). Reference the `auth.users` table to ensure data integrity. Specify `on delete cascade` in the reference. For example, a `public.profiles` table might look like this: ```sql create table public.profiles ( id uuid not null references auth.users on delete cascade, first_name text, last_name text, primary key (id) ); alter table public.profiles enable row level security; ``` To update your `public.profiles` table every time a user signs up, set up a trigger. If the trigger fails, it could block signups, so test your code thoroughly. ```sql -- inserts a row into public.profiles create function public.handle_new_user() returns trigger language plpgsql security definer set search_path = '' as $$ begin insert into public.profiles (id, first_name, last_name) values (new.id, new.raw_user_meta_data ->> 'first_name', new.raw_user_meta_data ->> 'last_name'); return new; end; $$; -- trigger the function every time a user is created create trigger on_auth_user_created after insert on auth.users for each row execute procedure public.handle_new_user(); ``` ## Adding and retrieving user metadata You can assign metadata to users on sign up: User metadata is stored on the `raw_user_meta_data` column of the `auth.users` table. To view the metadata: ## Deleting users You may delete users directly or via the management console at Authentication > Users. Note that deleting a user from the `auth.users` table does not automatically sign out a user. As Supabase makes use of JSON Web Tokens (JWT), a user's JWT will remain "valid" until it has expired. Should you wish to immediately revoke access for a user, do consider making use of a Row Level Security policy as described below. ## Exporting users As Supabase is built on top of Postgres, you can query the `auth.users` and `auth.identities` table via the `SQL Editor` tab to extract all users: ```sql select * from auth.users; ``` You can then export the results as CSV. # Native Mobile Deep Linking Set up Deep Linking for mobile applications. Many Auth methods involve a redirect to your app. For example: * Signup confirmation emails, Magic Link signins, and password reset emails contain a link that redirects to your app. * In OAuth signins, an automatic redirect occurs to your app. With Deep Linking, you can configure this redirect to open a specific page. This is necessary if, for example, you need to display a form for [password reset](/docs/guides/auth/passwords#resetting-a-users-password-forgot-password), or to manually exchange a token hash. ## Setting up deep linking # Password security Help your users to protect their password security A password is more secure if it is harder to guess or brute-force. In theory, a password is harder to guess if it is longer. It is also harder to guess if it uses a larger set of characters (for example, digits, lowercase and uppercase letters, and symbols). This table shows the *minimum* number of guesses that need to be tried to access a user's account: | Required characters | Length | Guesses | | -------------------------------------------- | ------ | ---------------- | | Digits only | 8 | ~ 2 | | Digits and letters | 8 | ~ 2 | | Digits, lower and uppercase letters | 8 | ~ 2 | | Digits, lower and uppercase letters, symbols | 8 | ~ 2 | In reality though, passwords are not always generated at random. They often contain variations of names, words, dates, and common phrases. Malicious actors can use these properties to guess a password in fewer attempts. There are hundreds of millions (and growing!) known passwords out there. Malicious actors can use these lists of leaked passwords to automate login attempts (known as credential stuffing) and steal or access sensitive user data. ## Password strength and leaked password protection To help protect your users, Supabase Auth allows you fine-grained control over the strength of the passwords used on your project. You can configure these in your project's [Auth settings](/dashboard/project/_/auth/providers?provider=Email): * Set a large minimum password length. Anything less than 8 characters is not recommended. * Set the required characters that must appear at least once in a user's password. Use the strongest option of requiring digits, lowercase and uppercase letters, and symbols. * Prevent the use of leaked passwords. Supabase Auth uses the open-source [HaveIBeenPwned.org Pwned Passwords API](https://haveibeenpwned.com/Passwords) to reject passwords that have been leaked and are known by malicious actors. ## Additional recommendations In addition to choosing suitable password strength settings and preventing the use of leaked passwords, consider asking your users to: * Use a password manager to store and generate passwords. * Avoid password reuse across websites and apps. * Avoid using personal information in passwords. * Use [Multi-Factor Authentication](/docs/guides/auth/auth-mfa). ## Frequently asked questions ### How are passwords stored? Supabase Auth uses [bcrypt](https://en.wikipedia.org/wiki/Bcrypt), a strong password hashing function, to store hashes of users' passwords. Only hashed passwords are stored. You cannot impersonate a user with the password hash. Each hash is accompanied by a randomly generated salt parameter for extra security. The hash is stored in the `encrypted_password` column of the `auth.users` table. The column's name is a misnomer (cryptographic hashing is not encryption), but is kept for backward compatibility. ### How will strengthened password requirements affect current users? Existing users can still sign in with their current password even if it doesn't meet the new, strengthened password requirements. However, if their password falls short of these updated standards, they will encounter a `WeakPasswordError` during the `signInWithPassword` process, explaining why it's considered weak. This change is also applicable to new users and existing users changing their passwords, ensuring everyone adheres to the enhanced security standards. # Password-based Auth Allow users to sign in with a password connected to their email or phone number. Users often expect to sign in to your site with a password. Supabase Auth helps you implement password-based auth safely, using secure configuration options and best practices for storing and verifying passwords. Users can associate a password with their identity using their [email address](#with-email) or a [phone number](#with-phone). ## With email ### Enabling email and password-based authentication Email authentication is enabled by default. You can configure whether users need to verify their email to sign in. On hosted Supabase projects, this is true by default. On self-hosted projects or in local development, this is false by default. Change this setting on the [Auth Providers page](/dashboard/project/_/auth/providers) for hosted projects, or in the [configuration file](/docs/guides/cli/config#auth.email.enable_confirmations) for self-hosted projects. ### Signing up with an email and password There are two possible flows for email signup: [implicit flow](/docs/guides/auth/sessions#implicit-flow) and [PKCE flow](/docs/guides/auth/sessions#pkce-flow). If you're using SSR, you're using the PKCE flow. If you're using client-only code, the default flow depends upon the client library. The implicit flow is the default in JavaScript and Dart, and the PKCE flow is the default in Swift. The instructions in this section assume that email confirmations are enabled. ### Signing in with an email and password ### Resetting a password ### Email sending The signup confirmation and password reset flows require an SMTP server to send emails. The Supabase platform comes with a default email-sending service for you to try out. The service has a rate limit of emails per hour, and availability is on a best-effort basis. For production use, you should consider configuring a custom SMTP server. See the [Custom SMTP guide](/docs/guides/auth/auth-smtp) for instructions. #### Local development with Inbucket You can test email flows on your local machine. The Supabase CLI automatically captures emails sent locally by using [Inbucket](https://github.com/inbucket/inbucket). In your terminal, run `supabase status` to get the Inbucket URL. Go to this URL in your browser, and follow the instructions to find your emails. ## With phone You can use a user's mobile phone number as an identifier, instead of an email address, when they sign up with a password. This practice is usually discouraged because phone networks recycle mobile phone numbers. Anyone receiving a recycled phone number gets access to the original user's account. To mitigate this risk, [implement MFA](/docs/guides/auth/auth-mfa). ### Enabling phone and password-based authentication Enable phone authentication on the [Auth Providers page](/dashboard/project/_/auth/providers) for hosted Supabase projects. For self-hosted projects or local development, use the [configuration file](/docs/guides/cli/config#auth.sms.enable_signup). See the configuration variables namespaced under `auth.sms`. If you want users to confirm their phone number on signup, you need to set up an SMS provider. Each provider has its own configuration. Supported providers include MessageBird, Twilio, Vonage, and TextLocal (community-supported). ### Signing up with a phone number and password To sign up the user, call [`signUp()`](/docs/reference/javascript/auth-signup) with their phone number and password: If you have phone verification turned on, the user receives an SMS with a 6-digit pin that you must verify within 60 seconds: ### Signing in a with a phone number and password Call the function to sign in with the user's phone number and password: # Phone Login Phone Login is a method of authentication that allows users to log in to a website or application without using a password. The user authenticates through a one-time password (OTP) sent via a channel (SMS or WhatsApp). Users can also log in with their phones using Native Mobile Login with the built-in identity provider. For Native Mobile Login with Android and iOS, see the [Social Login guides](/docs/guides/auth/social-login). Phone OTP login can: * Improve the user experience by not requiring users to create and remember a password * Increase security by reducing the risk of password-related security breaches * Reduce support burden of dealing with password resets and other password-related flows ## Enabling phone login Enable phone authentication on the [Auth Providers page](/dashboard/project/_/auth/providers) for hosted Supabase projects. For self-hosted projects or local development, use the [configuration file](/docs/guides/cli/config#auth.sms.enable_signup). See the configuration variables namespaced under `auth.sms`. You also need to set up an SMS provider. Each provider has its own configuration. Supported providers include MessageBird, Twilio, Vonage, and TextLocal (community-supported). By default, a user can only request an OTP once every and they expire after . ## Signing in with phone OTP With OTP, a user can sign in without setting a password on their account. They need to verify their phone number each time they sign in. The user receives an SMS with a 6-digit pin that you must verify within 60 seconds. ## Verifying a phone OTP To verify the one-time password (OTP) sent to the user's phone number, call [`verifyOtp()`](/docs/reference/javascript/auth-verifyotp) with the phone number and OTP: If successful the user will now be logged in and you should receive a valid session like: ```json { "access_token": "", "token_type": "bearer", "expires_in": 3600, "refresh_token": "" } ``` The access token can be sent in the Authorization header as a Bearer token for any CRUD operations on supabase-js. See our guide on [Row Level Security](/docs/guides/auth#row-level-security) for more info on restricting access on a user basis. ## Updating a phone number To update a user's phone number, the user must be logged in. Call [`updateUser()`](/docs/reference/javascript/auth-updateuser) with their phone number: The user receives an SMS with a 6-digit pin that you must [verify](#verifying-a-phone-otp) within 60 seconds. Use the `phone_change` type when calling `verifyOTP` to update a user’s phone number. # Use Supabase Auth with Next.js Learn how to configure Supabase Auth for the Next.js App Router. ## Learn more * [Setting up Server-Side Auth for Next.js](https://supabase.com/docs/guides/auth/server-side/nextjs) for a Next.js deep dive * [Supabase Auth docs](https://supabase.com/docs/guides/auth#authentication) for more Supabase authentication methods # Use Supabase Auth with React Native Learn how to use Supabase Auth with React Native # Use Supabase Auth with React Learn how to use Supabase Auth with React.js. # Rate limits Rate limits protect your services from abuse Supabase Auth enforces rate limits on endpoints to prevent abuse. Some rate limits are [customizable](/dashboard/project/_/auth/rate-limits). # Redirect URLs Set up redirect urls with Supabase Auth. ## Overview When using [passwordless sign-ins](/docs/reference/javascript/auth-signinwithotp) or [third-party providers](/docs/reference/javascript/auth-signinwithoauth#sign-in-using-a-third-party-provider-with-redirect), the Supabase client library methods provide a `redirectTo` parameter to specify where to redirect the user to after authentication. By default, the user will be redirected to the [`SITE_URL`](/docs/guides/auth/redirect-urls) but you can modify the `SITE_URL` or add additional redirect URLs to the allow list. Once you've added necessary URLs to the allow list, you can specify the URL you want the user to be redirected to in the `redirectTo` parameter. To edit the allow list, go to the [URL Configuration](/dashboard/project/_/auth/url-configuration) page. In local development or self-hosted projects, use the [configuration file](/docs/guides/cli/config#auth.additional_redirect_urls). ## Use wildcards in redirect URLs Supabase allows you to specify wildcards when adding redirect URLs to the [allow list](https://supabase.com/dashboard/project/_/auth/url-configuration). You can use wildcard match patterns to support preview URLs from providers like Netlify and Vercel. | Wildcard | Description | | ------------------------ | ------------------------------------------------------------------------------------------------------------------------------------------ | | `*` | matches any sequence of non-separator characters | | `**` | matches any sequence of characters | | `?` | matches any single non-separator character | | `c` | matches character c (c != `*`, `**`, `?`, `\`, `[`, `{`, `}`) | | `\c` | matches character c | | `[!{ character-range }]` | matches any sequence of characters not in the `{ character-range }`. For example, `[!a-z]` will not match any characters ranging from a-z. | The separator characters in a URL are defined as `.` and `/`. Use [this tool](https://www.digitalocean.com/community/tools/glob?comments=true\&glob=http%3A%2F%2Flocalhost%3A3000%2F%2A%2A\&matches=false\&tests=http%3A%2F%2Flocalhost%3A3000\&tests=http%3A%2F%2Flocalhost%3A3000%2F\&tests=http%3A%2F%2Flocalhost%3A3000%2F%3Ftest%3Dtest\&tests=http%3A%2F%2Flocalhost%3A3000%2Ftest-test%3Ftest%3Dtest\&tests=http%3A%2F%2Flocalhost%3A3000%2Ftest%2Ftest%3Ftest%3Dtest) to test your patterns. ### Redirect URL examples with wildcards | Redirect URL | Description | | ------------------------------ | ------------------------------------------------------------------------------------------------------------------------------------------------------------------ | | `http://localhost:3000/*` | matches `http://localhost:3000/foo`, `http://localhost:3000/bar` but not `http://localhost:3000/foo/bar` or `http://localhost:3000/foo/` (note the trailing slash) | | `http://localhost:3000/**` | matches `http://localhost:3000/foo`, `http://localhost:3000/bar` and `http://localhost:3000/foo/bar` | | `http://localhost:3000/?` | matches `http://localhost:3000/a` but not `http://localhost:3000/foo` | | `http://localhost:3000/[!a-z]` | matches `http://localhost:3000/1` but not `http://localhost:3000/a` | ## Netlify preview URLs For deployments with Netlify, set the `SITE_URL` to your official site URL. Add the following additional redirect URLs for local development and deployment previews: * `http://localhost:3000/**` * `https://**--my_org.netlify.app/**` ## Vercel preview URLs For deployments with Vercel, set the `SITE_URL` to your official site URL. Add the following additional redirect URLs for local development and deployment previews: * `http://localhost:3000/**` * `https://*-.vercel.app/**` Vercel provides an environment variable for the URL of the deployment called `NEXT_PUBLIC_VERCEL_URL`. See the [Vercel docs](https://vercel.com/docs/concepts/projects/environment-variables#system-environment-variables) for more details. You can use this variable to dynamically redirect depending on the environment. You should also set the value of the environment variable called NEXT\_PUBLIC\_SITE\_URL, this should be set to your site URL in production environment to ensure that redirects function correctly. ```js const getURL = () => { let url = process?.env?.NEXT_PUBLIC_SITE_URL ?? // Set this to your site URL in production env. process?.env?.NEXT_PUBLIC_VERCEL_URL ?? // Automatically set by Vercel. 'http://localhost:3000/' // Make sure to include `https://` when not localhost. url = url.startsWith('http') ? url : `https://${url}` // Make sure to include a trailing `/`. url = url.endsWith('/') ? url : `${url}/` return url } const { data, error } = await supabase.auth.signInWithOAuth({ provider: 'github', options: { redirectTo: getURL(), }, }) ``` ## Email templates when using `redirectTo` When using a `redirectTo` option, you may need to replace the `{{ .SiteURL }}` with `{{ .RedirectTo }}` in your email templates. See the [Email Templates guide](/docs/guides/auth/auth-email-templates) for more information. For example, change the following: ```html Confirm your mail Confirm your mail ``` ## Mobile deep linking URIs For mobile applications you can use deep linking URIs. For example, for your `SITE_URL` you can specify something like `com.supabase://login-callback/` and for additional redirect URLs something like `com.supabase.staging://login-callback/` if needed. Read more about deep linking and find code examples for different frameworks [here](/docs/guides/auth/native-mobile-deep-linking). ## Error handling When authentication fails, the user will still be redirected to the redirect URL provided. However, the error details will be returned as query fragments in the URL. You can parse these query fragments and show a custom error message to the user. For example: ```js const params = new URLSearchParams(window.location.hash.slice()) if (params.get('error_code').startsWith('4')) { // show error message if error is a 4xx error window.alert(params.get('error_description')) } ``` # Server-Side Rendering How SSR works with Supabase Auth. SSR frameworks move rendering and data fetches to the server, to reduce client bundle size and execution time. Supabase Auth is fully compatible with SSR. You need to make a few changes to the configuration of your Supabase client, to store the user session in cookies instead of local storage. After setting up your Supabase client, follow the instructions for any flow in the How-To guides. ## `@supabase/ssr` We have developed an [`@supabase/ssr`](https://www.npmjs.com/package/@supabase/ssr) package to make setting up the Supabase client as simple as possible. This package is currently in beta. Adoption is recommended but be aware that the API is still unstable and may have breaking changes in the future. ## Framework quickstarts # Advanced guide Details about SSR Auth flows and implementation for advanced users. When a user authenticates with Supabase Auth, two pieces of information are issued by the server: 1. **Access token** in the form of a JWT. 2. **Refresh token** which is a randomly generated string. The default behavior if you're not using SSR is to store this information in local storage. Local storage isn't accessible by the server, so for SSR, the tokens instead need to be stored in a secure cookie. The cookie can then be passed back and forth between your app code in the client and your app code in the server. If you're not using SSR, you might also be using the [implicit flow](/docs/guides/auth/sessions/implicit-flow) to get the access and refresh tokens. The server can't access the tokens in this flow, so for SSR, you should change to the [PKCE flow](/docs/guides/auth/sessions/pkce-flow). You can change the flow type when initiating your Supabase client if your client library provides this option. ## How it works In the PKCE flow, a redirect is made to your app, with an Auth Code contained in the URL. When you exchange this code using `exchangeCodeForSession`, you receive the session information, which contains the access and refresh tokens. To maintain the session, these tokens must be stored in a storage medium securely shared between client and server, which is traditionally cookies. Whenever the session is refreshed, the auth and refresh tokens in the shared storage medium must be updated. Supabase client libraries provide a customizable `storage` option when a client is initiated, allowing you to change where tokens are stored. For an implementation example, see the [@supabase/ssr](https://github.com/supabase/auth-helpers/blob/main/packages/ssr/src/index.ts) package. ## Frequently asked questions ### No session on the server side with Next.js route prefetching? When you use route prefetching in Next.js using `` components or the `Router.push()` APIs can send server-side requests before the browser processes the access and refresh tokens. This means that those requests may not have any cookies set and your server code will render unauthenticated content. To improve experience for your users, we recommend redirecting users to one specific page after sign-in that does not include any route prefetching from Next.js. Once the Supabase client library running in the browser has obtained the access and refresh tokens from the URL fragment, you can send users to any pages that use prefetching. ### How do I make the cookies `HttpOnly`? This is not necessary. Both the access token and refresh token are designed to be passed around to different components in your application. The browser-based side of your application needs access to the refresh token to properly maintain a browser session anyway. ### My server is getting invalid refresh token errors. What's going on? It is likely that the refresh token sent from the browser to your server is stale. Make sure the `onAuthStateChange` listener callback is free of bugs and is registered relatively early in your application's lifetime When you receive this error on the server-side, try to defer rendering to the browser where the client library can access an up-to-date refresh token and present the user with a better experience. ### Should I set a shorter `Max-Age` parameter on the cookies? The `Max-Age` or `Expires` cookie parameters only control whether the browser sends the value to the server. Since a refresh token represents the long-lived authentication session of the user on that browser, setting a short `Max-Age` or `Expires` parameter on the cookies only results in a degraded user experience. The only way to ensure that a user has logged out or their session has ended is to get the user's details with `getUser()`. ### What should I use for the `SameSite` property? Make sure you [understand the behavior of the property in different situations](https://developer.mozilla.org/en-US/docs/Web/HTTP/Headers/Set-Cookie/SameSite) as some properties can degrade the user experience. A good default is to use `Lax` which sends cookies when users are navigating to your site. Cookies typically require the `Secure` attribute, which only sends them over HTTPS. However, this can be a problem when developing on `localhost`. ### Can I use server-side rendering with a CDN or cache? Yes, but you need to be careful to include at least the refresh token cookie value in the cache key. Otherwise you may be accidentally serving pages with data belonging to different users! Also be sure you set proper cache control headers. We recommend invalidating cache keys every hour or less. ### Which authentication flows have PKCE support? At present, PKCE is supported on the Magic Link, OAuth, Sign Up, and Password Recovery routes. These correspond to the `signInWithOtp`, `signInWithOAuth`, `signUp`, and `resetPasswordForEmail` methods on the Supabase client library. When using PKCE with Phone and Email OTPs, there is no behavior change with respect to the implicit flow - an access token will be returned in the body when a request is successful. # Creating a Supabase client for SSR Configure your Supabase client to use cookies To use Server-Side Rendering (SSR) with Supabase, you need to configure your Supabase client to use cookies. The `@supabase/ssr` package helps you do this for JavaScript/TypeScript applications. ## Install Install the `@supabase/ssr` and `@supabase/supabase-js` packages: ## Set environment variables In your environment variables file, set your Supabase URL and Supabase Anon Key: ## Create a client You'll need some one-time setup code to configure your Supabase client to use cookies. Once your utility code is set up, you can use your new `createClient` utility functions to get a properly configured Supabase client. Use the browser client in code that runs on the browser, and the server client in code that runs on the server. ## Next steps * Implement [Authentication using Email and Password](/docs/guides/auth/server-side/email-based-auth-with-pkce-flow-for-ssr) * Implement [Authentication using OAuth](/docs/guides/auth/server-side/oauth-with-pkce-flow-for-ssr) * [Learn more about SSR](/docs/guides/auth/server-side-rendering) # Migrating to the SSR package from Auth Helpers The new `ssr` package takes the core concepts of the Auth Helpers and makes them available to any server language or framework. This page will guide you through migrating from the Auth Helpers package to `ssr`. ### Replacing Supabase packages ```bash npm install @supabase/ssr ``` ### Creating a client The new `ssr` package exports two functions for creating a Supabase client. The `createBrowserClient` function is used in the client, and the `createServerClient` function is used in the server. Check out the [Creating a client](/docs/guides/auth/server-side/creating-a-client) page for examples of creating a client in your framework. ## Next steps * Implement [Authentication using Email and Password](/docs/guides/auth/server-side/email-based-auth-with-pkce-flow-for-ssr) * Implement [Authentication using OAuth](/docs/guides/auth/server-side/oauth-with-pkce-flow-for-ssr) * [Learn more about SSR](/docs/guides/auth/server-side-rendering) # Setting up Server-Side Auth for Next.js Next.js comes in two flavors: the [App Router](https://nextjs.org/docs/app) and the [Pages Router](https://nextjs.org/docs/pages). You can set up Server-Side Auth with either strategy. You can even use both in the same application. # Setting up Server-Side Auth for SvelteKit Set up Server-Side Auth to use cookie-based authentication with SvelteKit. # User sessions Supabase Auth provides fine-grained control over your user's sessions. Some security sensitive applications, or those that need to be SOC 2, HIPAA, PCI-DSS or ISO27000 compliant will require some sort of additional session controls to enforce timeouts or provide additional security guarantees. Supabase Auth makes it easy to build compliant applications. ## What is a session? A session is created when a user signs in. By default, it lasts indefinitely and a user can have an unlimited number of active sessions on as many devices. A session is represented by the Supabase Auth access token in the form of a JWT, and a refresh token which is a unique string. Access tokens are designed to be short lived, usually between 5 minutes and 1 hour while refresh tokens never expire but can only be used once. You can exchange a refresh token only once to get a new access and refresh token pair. This process is called **refreshing the session.** A session terminates, depending on configuration, when: * The user clicks sign out. * The user changes their password or performs a security sensitive action. * It times out due to inactivity. * It reaches its maximum lifetime. * A user signs in on another device. ## Access token (JWT) claims Every access token contains a `session_id` claim, a UUID, uniquely identifying the session of the user. You can correlate this ID with the primary key of the `auth.sessions` table. ## Initiating a session A session is initiated when a user signs in. The session is stored in the `auth.sessions` table, and your app should receive the access and refresh tokens. There are two flows for initiating a session and receiving the tokens: * [Implicit flow](/docs/guides/auth/sessions/implicit-flow) * [PKCE flow](/docs/guides/auth/sessions/pkce-flow) ## Limiting session lifetime and number of allowed sessions per user Supabase Auth can be configured to limit the lifetime of a user's session. By default, all sessions are active until the user signs out or performs some other action that terminates a session. In some applications, it's useful or required for security to ensure that users authenticate often, or that sessions are not left active on devices for too long. There are three ways to limit the lifetime of a session: * Time-boxed sessions, which terminate after a fixed amount of time. * Set an inactivity timeout, which terminates sessions that haven't been refreshed within the timeout duration. * Enforce a single-session per user, which only keeps the most recently active session. To make sure that users are required to re-authenticate periodically, you can set a positive value for the **Time-box user sessions** option in the [Auth settings](/dashboard/project/_/settings/auth) for your project. To make sure that sessions expire after a period of inactivity, you can set a positive duration for the **Inactivity timeout** option in the [Auth settings](/dashboard/project/_/settings/auth). You can also enforce only one active session per user per device or browser. When this is enabled, the session from the most recent sign in will remain active, while the rest are terminated. Enable this via the *Single session per user* option in the [Auth settings](/dashboard/project/_/settings/auth). Sessions are not proactively destroyed when you change these settings, but rather the check is enforced whenever a session is refreshed next. This can confuse developers because the actual duration of a session is the configured timeout plus the JWT expiration time. For single session per user, the effect will only be noticed at intervals of the JWT expiration time. Make sure you adjust this setting depending on your needs. We do not recommend going below 5 minutes for the JWT expiration time. Otherwise sessions are progressively deleted from the database 24 hours after they expire, which prevents you from causing a high load on your project by accident and allows you some freedom to undo changes without adversely affecting all users. ## Frequently asked questions ### What are recommended values for access token (JWT) expiration? Most applications should use the default expiration time of 1 hour. This can be customized in your project's [Auth settings](/dashboard/project/_/settings/auth) in the Advanced Settings section. Setting a value over 1 hour is generally discouraged for security reasons, but it may make sense in certain situations. Values below 5 minutes, and especially below 2 minutes, should not be used in most situations because: * The shorter the expiration time, the more frequently refresh tokens are used, which increases the load on the Auth server. * Time is not absolute. Servers can often be off sync for tens of seconds, but user devices like laptops, desktops or mobile devices can sometimes be off by minutes or even hours. Having too short expiration time can cause difficult-to-debug errors due to clock skew. * Supabase's client libraries always try to refresh the session ahead of time, which won't be possible if the expiration time is too short. * Access tokens should generally be valid for at least as long as the longest running request in your application. This helps you avoid issues where the access token becomes invalid midway through processing. ### What is refresh token reuse detection and what does it protect from? As your users continue using your app, refresh tokens are being constantly exchanged for new access tokens. The general rule is that a refresh token can only be used once. However, strictly enforcing this can cause certain issues to arise. There are two exceptions to this design to prevent the early and unexpected termination of user's sessions: * A refresh token can be used more than once within a defined reuse interval. By default this is 10 seconds and we do not recommend changing this value. This exception is granted for legitimate situations such as: * Using server-side rendering where the same refresh token needs to be reused on the server and soon after on the client * To allow some leeway for bugs or issues with serializing access to the refresh token request * If the parent of the currently active refresh token for the user's session is being used, the active token will be returned. This exception solves an important and often common situation: * All clients such as browsers, mobile or desktop apps, and even some servers are inherently unreliable due to network issues. A request does not indicate that they received a response or even processed the response they received. * If a refresh token is revoked after being used only once, and the response wasn't received and processed by the client, when the client comes back online, it will attempt to use the refresh token that was already used. Since this might happen outside of the reuse interval, it can cause sudden and unexpected session termination. Should the reuse attempt not fall under these two exceptions, the whole session is regarded as terminated and all refresh tokens belonging to it are marked as revoked. You can disable this behavior in the Advanced Settings of the [Auth settings](/dashboard/project/_/settings/auth) page, though it is generally not recommended. The purpose of this mechanism is to guard against potential security issues where a refresh token could have been stolen from the user, for example by exposing it accidentally in logs that leak (like logging cookies, request bodies or URL params) or via vulnerable third-party servers. It does not guard against the case where a user's session is stolen from their device. ### What are the benefits of using access and refresh tokens instead of traditional sessions? Traditionally user sessions were implemented by using a unique string stored in cookies that identified the authorization that the user had on a specific browser. Applications would use this unique string to constantly fetch the attached user information on every API call. This approach has some tradeoffs compared to using a JWT-based approach: * If the authentication server or its database crashes or is unavailable for even a few seconds, the whole application goes down. Scheduling maintenance or dealing with transient errors becomes very challenging. * A failing authentication server can cause a chain of failures across other systems and APIs, paralyzing the whole application system. * All requests that require authentication has to be routed through the authentication, which adds an additional latency overhead to all requests. Supabase Auth prefers a JWT-based approach using access and refresh tokens because session information is encoded within the short-lived access token, enabling transfer across APIs and systems without dependence on a central server's availability or performance. This approach enhances an application's tolerance to transient failures or performance issues. Furthermore, proactively refreshing the access token allows the application to function reliably even during significant outages. It's better for cost optimization and scaling as well, as the authentication system's servers and database only handle traffic for this use case. ### How to ensure an access token (JWT) cannot be used after a user signs out Most applications rarely need such strong guarantees. Consider adjusting the JWT expiry time to an acceptable value. If this is still necessary, you should try to use this validation logic only for the most sensitive actions within your application. When a user signs out, the sessions affected by the logout are removed from the database entirely. You can check that the `session_id` claim in the JWT corresponds to a row in the `auth.sessions` table. If such a row does not exist, it means that the user has logged out. Note that sessions are not proactively terminated when their maximum lifetime (time-box) or inactivity timeout are reached. These sessions are cleaned up progressively 24 hours after reaching that status. This allows you to tweak the values or roll back changes without causing unintended user friction. ### Using HTTP-only cookies to store access and refresh tokens This is possible, but only for apps that use the traditional server-only web app approach where all of the application logic is implemented on the server and it returns rendered HTML only. If your app uses any client side JavaScript to build a rich user experience, using HTTP-Only cookies is not feasible since only your server will be able to read and refresh the session of the user. The browser will not have access to the access and refresh tokens. Because of this, the Supabase JavaScript libraries provide only limited support. You can override the `storage` option when creating the Supabase client **on the server** to store the values in cookies or your preferred storage choice, for example: ```typescript import { createClient } from '@supabase/supabase-js' const supabase = createClient('SUPABASE_URL', 'SUPABASE_ANON_KEY', { auth: { storage: { getItem: () => { return Promise.resolve('FETCHED_COOKIE') }, setItem: () => {}, removeItem: () => {}, }, }, }) ``` The `customStorageObject` should implement the `getItem`, `setItem`, and `removeItem` methods from the [`Storage` interface](https://developer.mozilla.org/en-US/docs/Web/API/Storage). Async versions of these methods are also supported. When using cookies to store access and refresh tokens, make sure that the [`Expires` or `Max-Age` attributes](https://developer.mozilla.org/en-US/docs/Web/HTTP/Headers/Set-Cookie#attributes) of the cookies is set to a timestamp very far into the future. Browsers will clear the cookies, but the session will remain active in Supabase Auth. Therefore it's best to let Supabase Auth control the validity of these tokens and instruct the browser to always store the cookies indefinitely. # Implicit flow About authenticating with implicit flow. The implicit flow is one of two ways that a user can authenticate and your app can receive the necessary access and refresh tokens. The flow is an implementation detail handled for you by Supabase Auth, but understanding the difference between implicit and [PKCE flow](/docs/guides/auth/sessions/pkce-flow) is important for understanding the difference between client-only and server-side auth. ## How it works After a successful signin, the user is redirected to your app with a URL that looks like this: https://yourapp.com/...#access_token=<...>&refresh_token=<...>&... The access and refresh tokens are contained in the URL fragment. The client libraries: * Detect this type of URL * Extract the access token, refresh token, and some extra information * Persist this information to local storage for further use by the library and your app ## Limitations The implicit flow only works on the client. Web browsers do not send the URL fragment to the server by design. This is a security feature: * You may be hosting your single-page app on a third-party server. The third-party service shouldn't get access to your user's credentials. * Even if the server is under your direct control, `GET` requests and their full URLs are often logged. This approach avoids leaking credentials in request or access logs. If you wish to obtain the access token and refresh token on a server, use the [PKCE flow](/docs/guides/auth/sessions/pkce-flow). # PKCE flow About authenticating with PKCE flow. The Proof Key for Code Exchange (PKCE) flow is one of two ways that a user can authenticate and your app can receive the necessary access and refresh tokens. The flow is an implementation detail handled for you by Supabase Auth, but understanding the difference between PKCE and [implicit flow](/docs/guides/auth/sessions/implicit-flow) is important for understanding the difference between client-only and server-side auth. ## How it works After a successful verification, the user is redirected to your app with a URL that looks like this: https://yourapp.com/...?code=<...> The `code` parameter is commonly known as the Auth Code and can be exchanged for an access token by calling `exchangeCodeForSession(code)`. As the flow is run server side, `localStorage` may not be available. You may configure the client library to use a custom storage adapter and an alternate backing storage such as cookies by setting the `storage` option to an object with the following methods: ```js import { type SupportedStorage } from '@supabase/supabase-js'; const supportsLocalStorage = () => true // ---cut--- const customStorageAdapter: SupportedStorage = { getItem: (key) => { if (!supportsLocalStorage()) { // Configure alternate storage return null } return globalThis.localStorage.getItem(key) }, setItem: (key, value) => { if (!supportsLocalStorage()) { // Configure alternate storage here return } globalThis.localStorage.setItem(key, value) }, removeItem: (key) => { if (!supportsLocalStorage()) { // Configure alternate storage here return } globalThis.localStorage.removeItem(key) }, } ``` You may also configure the client library to automatically exchange it for a session after a successful redirect. This can be done by setting the `detectSessionInUrl` option to `true`. Putting it all together, your client library initialization may look like this: ```js import { createClient } from '@supabase/supabase-js' // ---cut--- const supabase = createClient('https://xyzcompany.supabase.co', 'public-anon-key', { // ... auth: { // ... detectSessionInUrl: true, flowType: 'pkce', storage: { getItem: () => Promise.resolve('FETCHED_TOKEN'), setItem: () => {}, removeItem: () => {}, }, }, // ... }) ``` ## Limitations Behind the scenes, the code exchange requires a code verifier. Both the code in the URL and the code verifier are sent back to the Auth server for a successful exchange. The code verifier is created and stored locally when the Auth flow is first initiated. That means the code exchange must be initiated on the same browser and device where the flow was started. ## Resources * [OAuth 2.0 guide](https://oauth.net/2/pkce/) to PKCE flow # Signing out Signing out a user Signing out a user works the same way no matter what method they used to sign in. Call the sign out method from the client library. It removes the active session and clears Auth data from the storage medium. ## Sign out and scopes Supabase Auth allows you to specify three different scopes for when a user invokes the [sign out API](/docs/reference/javascript/auth-signout) in your application: * `global` (default) when all sessions active for the user are terminated. * `local` which only terminates the current session for the user but keep sessions on other devices or browsers active. * `others` to terminate all but the current session for the user. You can invoke these by providing the `scope` option: Upon sign out, all refresh tokens and potentially other database objects related to the affected sessions are destroyed and the client library removes the session stored in the local storage medium. # Social Login Social Login (OAuth) is an open standard for authentication that allows users to log in to one website or application using their credentials from another website or application. OAuth allows users to grant third-party applications access to their online accounts without sharing their passwords. OAuth is commonly used for things like logging in to a social media account from a third-party app. It is a secure and convenient way to authenticate users and share information between applications. ## Benefits There are several reasons why you might want to add social login to your applications: * **Improved user experience**: Users can register and log in to your application using their existing social media accounts, which can be faster and more convenient than creating a new account from scratch. This makes it easier for users to access your application, improving their overall experience. * **Better user engagement**: You can access additional data and insights about your users, such as their interests, demographics, and social connections. This can help you tailor your content and marketing efforts to better engage with your users and provide a more personalized experience. * **Increased security**: Social login can improve the security of your application by leveraging the security measures and authentication protocols of the social media platforms that your users are logging in with. This can help protect against unauthorized access and account takeovers. ## Set up a social provider with Supabase Auth Supabase supports a suite of social providers. Follow these guides to configure a social provider for your platform. ## Provider tokens You can use the provider token and provider refresh token returned to make API calls to the OAuth provider. For example, you can use the Google provider token to access Google APIs on behalf of your user. Supabase Auth does not manage refreshing the provider token for the user. Your application will need to use the provider refresh token to obtain a new provider token. If no provider refresh token is returned, then it could mean one of the following: * The OAuth provider does not return a refresh token * Additional scopes need to be specified in order for the OAuth provider to return a refresh token. Provider tokens are intentionally not stored in your project's database. This is because provider tokens give access to potentially sensitive user data in third-party systems. Different applications have different needs, and one application's OAuth scopes may be significantly more permissive than another. If you want to use the provider token outside of the browser that completed the OAuth flow, it is recommended to send it to a trusted and secure server you control. # Login with Apple Supabase Auth supports using [Sign in with Apple](https://developer.apple.com/sign-in-with-apple/) on the web and in native apps for iOS, macOS, watchOS or tvOS. ## Overview To support Sign in with Apple, you need to configure the [Apple provider in the Supabase dashboard](https://supabase.com/dashboard/project/_/auth/providers) for your project. There are three general ways to use Sign in with Apple, depending on the application you're trying to build: * Sign in on the web or in web-based apps * Using an OAuth flow initiated by Supabase Auth using the [Sign in with Apple REST API](https://developer.apple.com/documentation/sign_in_with_apple/sign_in_with_apple_rest_api). * Using [Sign in with Apple JS](https://developer.apple.com/documentation/sign_in_with_apple/sign_in_with_apple_js) directly in the browser, usually suitable for websites. * Sign in natively inside iOS, macOS, watchOS or tvOS apps using [Apple's Authentication Services](https://developer.apple.com/documentation/authenticationservices) In some cases you're able to use the OAuth flow within web-based native apps such as with [React Native](https://reactnative.dev), [Expo](https://expo.dev) or other similar frameworks. It is best practice to use native Sign in with Apple capabilities on those platforms instead. When developing with Expo, you can test Sign in with Apple via the Expo Go app, in all other cases you will need to obtain an [Apple Developer](https://developer.apple.com) account to enable the capability. # Login with Azure (Microsoft) To enable Azure (Microsoft) Auth for your project, you need to set up an Azure OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up OAuth with Azure consists of four broad steps: * Create an OAuth application under Azure Entra ID. * Add a secret to the application. * Add the Supabase Auth callback URL to the allowlist in the OAuth application in Azure. * Configure the client ID and secret of the OAuth application within the Supabase Auth dashboard. ## Access your Azure Developer account * Go to [portal.azure.com](https://portal.azure.com/#home). * Login and select Microsoft Entra ID under the list of Azure Services. ## Register an application * Under Microsoft Entra ID, select *App registrations* in the side panel and select *New registration.* * Choose a name and select your preferred option for the supported account types. * Specify a *Web* *Redirect URI*. It should look like this: `https://.supabase.co/auth/v1/callback` * Finally, select *Register* at the bottom of the screen. ![Register an application.](/docs/img/guides/auth-azure/azure-register-app.png) ## Obtain a client ID and secret * Once your app has been registered, the client ID can be found under the [list of app registrations](https://portal.azure.com/#blade/Microsoft_AAD_IAM/ActiveDirectoryMenuBlade/RegisteredApps) under the column titled *Application (client) ID*. * You can also find it in the app overview screen. * Place the Client ID in the Azure configuration screen in the Supabase Auth dashboard. ![Obtain the client ID](/docs/img/guides/auth-azure/azure-client-id.png) * Select *Add a certificate or secret* in the app overview screen and open the *Client secrets* tab. * Select *New client secret* to create a new client secret. * Choose a preferred expiry time of the secret. Make sure you record this in your calendar days in advance so you have enough time to create a new one without suffering from any downtime. * Once the secret is generated place the *Value* column (not *Secret ID*) in the Azure configuration screen in the Supabase Auth dashboard. ![Obtain the client secret](/docs/img/guides/auth-azure/azure-client-secret.png) ## Guarding against unverified email domains Microsoft Entra ID can send out unverified email domains in certain cases. This may open up your project to a vulnerability where a malicious user can impersonate already existing accounts on your project. This only applies in at least one of these cases: * You have configured the `authenticationBehaviors` setting of your OAuth application to allow unverified email domains * You are using an OAuth app configured as single-tenant in the supported account types * Your OAuth app was created before June 20th 2023 after Microsoft announced this vulnerability, and the app had used unverified emails prior This means that most OAuth apps *are not susceptible* to this vulnerability. Despite this, we recommend configuring the [optional `xms_edov` claim](https://learn.microsoft.com/en-us/azure/active-directory/develop/migrate-off-email-claim-authorization#using-the-xms_edov-optional-claim-to-determine-email-verification-status-and-migrate-users) on the OAuth app. This claim allows Supabase Auth to identify with certainty whether the email address sent over by Microsoft Entra ID is verified or not. Configure this in the following way: * Select the *App registrations* menu in Microsoft Entra ID on the Azure portal. * Select the OAuth app. * Select the *Manifest* menu in the sidebar. * Make a backup of the JSON just in case. * Identify the `optionalClaims` key. * Edit it by specifying the following object: ```json "optionalClaims": { "idToken": [ { "name": "xms_edov", "source": null, "essential": false, "additionalProperties": [] }, { "name": "email", "source": null, "essential": false, "additionalProperties": [] } ], "accessToken": [ { "name": "xms_edov", "source": null, "essential": false, "additionalProperties": [] } ], "saml2Token": [] }, ``` * Select *Save* to apply the new configuration. ## Configure a tenant URL (optional) A Microsoft Entra tenant is the directory of users who are allowed to access your project. This section depends on what your OAuth registration uses for *Supported account types.* By default, Supabase Auth uses the *common* Microsoft tenant (`https://login.microsoftonline.com/common`) which generally allows any Microsoft account to sign in to your project. Microsoft Entra further limits what accounts can access your project depending on the type of OAuth application you registered. If your app is registered as *Personal Microsoft accounts only* for the *Supported account types* set Microsoft tenant to *consumers* (`https://login.microsoftonline.com/consumers`). If your app is registered as *My organization only* for the *Supported account types* you may want to configure Supabase Auth with the organization's tenant URL. This will use the tenant's authorization flows instead, and will limit access at the Supabase Auth level to Microsoft accounts arising from only the specified tenant. Configure this by storing a value under *Azure Tenant URL* in the Supabase Auth provider configuration page for Azure that has the following format `https://login.microsoftonline.com/`. ## Add login code to your client app ## Obtain the provider refresh token Azure OAuth2.0 doesn't return the `provider_refresh_token` by default. If you need the `provider_refresh_token` returned, you will need to include the following scope: ## Resources * [Azure Developer Account](https://portal.azure.com) * [GitHub Discussion](https://github.com/supabase/gotrue/pull/54#issuecomment-757043573) * [Potential Risk of Privilege Escalation in Azure AD Applications](https://msrc.microsoft.com/blog/2023/06/potential-risk-of-privilege-escalation-in-azure-ad-applications/) # Login with Bitbucket To enable Bitbucket Auth for your project, you need to set up a Bitbucket OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up Bitbucket logins for your application consists of 3 parts: * Create and configure a Bitbucket OAuth Consumer on [Bitbucket](https://bitbucket.org) * Add your Bitbucket OAuth Consumer keys to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Access your Bitbucket account * Go to [bitbucket.org](https://bitbucket.org/). * Click on `Login` at the top right to log in. ![Bitbucket Developer Portal.](/docs/img/guides/auth-bitbucket/bitbucket-portal.png) ## Find your callback URL ## Create a Bitbucket OAuth app * Click on your profile icon at the bottom left * Click on `All Workspaces` * Select a workspace and click on it to select it * Click on `Settings` on the left * Click on `OAuth consumers` on the left under `Apps and Features` (near the bottom) * Click `Add Consumer` at the top * Enter the name of your app under `Name` * In `Callback URL`, type the callback URL of your app * Check the permissions you need (Email, Read should be enough) * Click `Save` at the bottom * Click on your app name (the name of your new OAuth Consumer) * Copy your `Key` (`client_key`) and `Secret` (`client_secret`) codes ## Add your Bitbucket credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Bitbucket Account](https://bitbucket.org) # Login with Discord To enable Discord Auth for your project, you need to set up a Discord Application and add the Application OAuth credentials to your Supabase Dashboard. ## Overview Setting up Discord logins for your application consists of 3 parts: * Create and configure a Discord Application [Discord Developer Portal](https://discord.com/developers) * Add your Discord OAuth Consumer keys to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Access your Discord account * Go to [discord.com](https://discord.com/). * Click on `Login` at the top right to log in. ![Discord Portal.](/docs/img/guides/auth-discord/discord-portal.png) * Once logged in, go to [discord.com/developers](https://discord.com/developers). ![Discord Portal.](/docs/img/guides/auth-discord/discord-developer-portal.png) ## Find your callback URL ## Create a Discord application * Click on `New Application` at the top right. * Enter the name of your application and click `Create`. * Click on `OAuth2` under `Settings` in the left side panel. * Click `Add Redirect` under `Redirects`. * Type or paste your `callback URL` into the `Redirects` box. * Click `Save Changes` at the bottom. * Copy your `Client ID` and `Client Secret` under `Client information`. ## Add your Discord credentials into your Supabase project ## Add login code to your client app If your user is already signed in, Discord prompts the user again for authorization. ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Discord Account](https://discord.com) * [Discord Developer Portal](https://discord.com/developers) # Login with Facebook To enable Facebook Auth for your project, you need to set up a Facebook OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up Facebook logins for your application consists of 3 parts: * Create and configure a Facebook Application on the [Facebook Developers Site](https://developers.facebook.com) * Add your Facebook keys to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Access your Facebook Developer account * Go to [developers.facebook.com](https://developers.facebook.com). * Click on `Log In` at the top right to log in. ![Facebook Developer Portal.](/docs/img/guides/auth-facebook/facebook-portal.png) ## Create a Facebook app * Click on `My Apps` at the top right. * Click `Create App` near the top right. * Select your app type and click `Continue`. * Fill in your app information, then click `Create App`. * This should bring you to the screen: `Add Products to Your App`. (Alternatively you can click on `Add Product` in the left sidebar to get to this screen.) ## Set up Facebook login for your Facebook app From the `Add Products to your App` screen: * Click `Setup` under `Facebook Login` * Skip the Quickstart screen, instead, in the left sidebar, click `Settings` under `Facebook Login` * Enter your callback URI under `Valid OAuth Redirect URIs` on the `Facebook Login Settings` page * Enter this in the `Valid OAuth Redirect URIs` box * Click `Save Changes` at the bottom right Be aware that you have to set the right use case permissions to enable Third party applications to read the email address. To do so: Under `Build Your App`, click on `Use Cases` screen. From there, do the following steps: * Click the Edit button in `Authentication and Account Creation` on the right side. This action will lead to the other page. * `public_profile` is set by default, so make sure it and `email` have status of **Ready for testing** in the redirected page. * If not, click the **Add** button in email on right side. ## Copy your Facebook app ID and secret * Click `Settings / Basic` in the left sidebar * Copy your App ID from the top of the `Basic Settings` page * Under `App Secret` click `Show` then copy your secret * Make sure all required fields are completed on this screen. ## Enter your Facebook app ID and secret into your Supabase project ## Add login code to your client app Now, you should be able to login with Facebook and alert you to `Submit for Login Review` when users try to sign into your app. Follow the instructions there to make your app go live for full features and products. You can read more about App Review [here](https://developers.facebook.com/docs/app-review/). ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Facebook Developers Dashboard](https://developers.facebook.com/) # Login with Figma To enable Figma Auth for your project, you need to set up a Figma OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up Figma logins for your application consists of 3 parts: * Create and configure a Figma App on the [Figma Developers page](https://www.figma.com/developers). * Add your Figma `client_id` and `client_secret` to your [Supabase Project](https://app.supabase.com). * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js). ## Access the Figma Developers page * Go to the [Figma Developers page](https://www.figma.com/developers) * Click on `My apps` at the top right * Log in (if necessary) ![Figma Developers page](/docs/img/guides/auth-figma/figma_developers_page.png) ## Find your callback URL ## Create a Figma OAuth app * Enter your `App name`, `Website URL` and upload your app logo * Click on `Add callback` * Add your `Callback URL` * Click on `Save` ![Create Figma app](/docs/img/guides/auth-figma/figma_create_app.png) * Copy and save your newly-generated `Client ID` * Copy and save your newly-generated `Client Secret` ![Get Figma app credentials](/docs/img/guides/auth-figma/figma_app_credentials.png) ## Enter your Figma credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Figma Developers page](https://www.figma.com/developers) # Login with GitHub To enable GitHub Auth for your project, you need to set up a GitHub OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up GitHub logins for your application consists of 3 parts: * Create and configure a GitHub OAuth App on [GitHub](https://github.com) * Add your GitHub OAuth keys to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Find your callback URL ## Register a new OAuth application on GitHub * Navigate to the [OAuth apps page](https://github.com/settings/developers) * Click `Register a new application`. If you've created an app before, click `New OAuth App` here. * In `Application name`, type the name of your app. * In `Homepage URL`, type the full URL to your app's website. * In `Authorization callback URL`, type the callback URL of your app. * Leave `Enable Device Flow` unchecked. * Click `Register Application`. Copy your new OAuth credentials * Copy and save your `Client ID`. * Click `Generate a new client secret`. * Copy and save your `Client secret`. ## Enter your GitHub credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [GitHub Developer Settings](https://github.com/settings/developers) # Login with GitLab To enable GitLab Auth for your project, you need to set up a GitLab OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up GitLab logins for your application consists of 3 parts: * Create and configure a GitLab Application on [GitLab](https://gitlab.com) * Add your GitLab Application keys to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Access your GitLab account * Go to [gitlab.com](https://gitlab.com). * Click on `Login` at the top right to log in. ![GitLab Developer Portal.](/docs/img/guides/auth-gitlab/gitlab-portal.png) ## Find your callback URL ## Create your GitLab application * Click on your `profile logo` (avatar) in the top-right corner. * Select `Edit profile`. * In the left sidebar, select Applications. * Enter the name of the application. * In the `Redirect URI` box, type the callback URL of your app. * Check the box next to `Confidential` (make sure it is checked). * Check the scope named `read_user` (this is the only required scope). * Click `Save Application` at the bottom. * Copy and save your `Application ID` (`client_id`) and `Secret` (`client_secret`) which you'll need later. ## Add your GitLab credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [GitLab Account](https://gitlab.com) # Login with Google Supabase Auth supports Sign in with Google for the web, native Android applications, and Chrome extensions. ## Prerequisites * A Google Cloud project. Go to the [Google Cloud Platform](https://console.cloud.google.com/home/dashboard) and create a new project if necessary. ## Configuration To support Sign In with Google, you need to configure the Google provider for your Supabase project. ## Signing users in ## Google consent screen ![Google Consent Screen](/docs/img/guides/auth-google/auth-google-consent-screen.png) By default, the Google consent screen shows the root domain of the callback URL, where Google will send the authentication response. With Supabase Auth, it is your Supabase project's domain `(https://.supabase.co)`. If that is not preferable, you can use a [Custom Domain](https://supabase.com/docs/guides/platform/custom-domains) with your Supabase project. You can use it as your project's domain when creating the Supabase client in your application and initiating the authentication flow. It will then show up in the Google consent screen. If you want your app name and the logo on the consent screen, [you must submit your app to Google for verification](https://support.google.com/cloud/answer/10311615). # Login with Kakao To enable Kakao Auth for your project, you need to set up an Kakao OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Kakao OAuth consists of six broad steps: * Create and configure your app in the [Kakao Developer Portal](https://developers.kakao.com). * Obtaining a `REST API key` - this will serve as the `client_id`. * Generating the `Client secret code` - this will serve as the `client_secret`. * Additional configurations on Kakao Developers Portal. * Add your `client id` and `client secret` keys to your [Supabase Project](https://supabase.com/dashboard). * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js). ## Access your Kakao Developer account * Go to [Kakao Developers Portal](https://developers.kakao.com). * Click on `Login` at the top right to log in. ![Kakao Developers Portal.](/docs/img/guides/auth-kakao/kakao-developers-page.png) ## Create and configure your app * Go to `My Application`. * Click on `Add an application` at the top. * Fill out your app information: * App icon. * App name. * Company name. * Click `Save` at the bottom right. ## Obtain a REST API key This will serve as the `client_id` when you make API calls to authenticate the user. * Go to `My Application`. * Click on your app. * You will be redirected to `Summary` tab of your app. * In the `App Keys` section you will see `REST API key` -- this ID will become your `client_id` later. ## Find your callback URL * To add callback URL on Kakao, go to `Product settings` > `Kakao Login` > `Redirect URI`. ## Generate and activate a `client_secret` * Go to `Product settings` > `Kakao Login` > `Security`. * Click on the `Kakao Login` switch to enable Kakao Login. * Click on `generate code` at the bottom to generate the `Client secret code` -- this will serve as a `client_secret` for your Supabase project. * Make sure you enabled `Client secret code` by selecting `enable` from the `Activation state` section. ## Additional configurations on Kakao Developers portal * Make sure the Kakao Login is enabled in the `Kakao Login` tab. * Set following scopes under the "Consent Items": account\_email, profile\_image, profile\_nickname ![Consent items needs to be set.](/docs/img/guides/auth-kakao/kakao-developers-consent-items-set.png) ## Add your OAuth credentials to Supabase ## Add login code to your client app ## Using Kakao Login JS SDK [Kakao Login JS SDK](https://developers.kakao.com/docs/latest/en/kakaologin/js) is an official Kakao SDK for authenticating Kakao users on websites. Exchange the [authorization code returned by Kakao API](https://developers.kakao.com/docs/latest/en/kakaologin/rest-api#request-code) for an [ID Token](https://developers.kakao.com/docs/latest/en/kakaologin/common#login-with-oidc). For example, this code shows a how to get ID Token: const requestUrl = new URL(request.url); const code = requestUrl.searchParams.get('code'); if (code) { const res = await fetch('https://kauth.kakao.com/oauth/token', { method: 'POST', headers: { 'Content-Type': 'application/x-www-form-urlencoded;charset=utf-8', }, body: new URLSearchParams({ grant_type: 'authorization_code', client_id: '', redirect_uri: '/api/auth/kakao/oidc', code, client_secret: '', }), }); const {id_token} = await res.json(); } Use the ID Token to sign in: const res = await auth.signInWithIdToken({ provider: 'kakao', token: id_token, }); ### Configuration 1. Set 'State' to 'ON' under [OpenID Connect Activation](https://developers.kakao.com/docs/latest/en/kakaologin/prerequisite#activate-oidc) on Kakao Developers portal Application Dashboard. 2. Add `openid` to [scope](https://developers.kakao.com/docs/latest/en/kakaologin/common#additional-consent-scope) along with the scope values you wish to obtain consent for. ## Resources * [Kakao Developers Portal](https://developers.kakao.com). # Login with Keycloak To enable Keycloak Auth for your project, you need to set up an Keycloak OAuth application and add the application credentials to your Supabase Dashboard. ## Overview To get started with Keycloak, you can run it in a docker container with: `docker run -p 8080:8080 -e KEYCLOAK_ADMIN=admin -e KEYCLOAK_ADMIN_PASSWORD=admin quay.io/keycloak/keycloak:latest start-dev` This guide will be assuming that you are running Keycloak in a docker container as described in the command above. Keycloak OAuth consists of five broad steps: * Create a new client in your specified Keycloak realm. * Obtain the `issuer` from the "OpenID Endpoint Configuration". This will be used as the `Keycloak URL`. * Ensure that the new client has the "Client Protocol" set to `openid-connect` and the "Access Type" is set to "confidential". * The `Client ID` of the client created will be used as the `client id`. * Obtain the `Secret` from the credentials tab which will be used as the `client secret`. * Add the callback URL of your application to your allowlist. ## Access your Keycloak admin console * Login by visiting [`http://localhost:8080`](http://localhost:8080) and clicking on "Administration Console". ## Create a Keycloak realm * Once you've logged in to the Keycloak console, you can add a realm from the side panel. The default realm should be named "Master". * After you've added a new realm, you can retrieve the `issuer` from the "OpenID Endpoint Configuration" endpoint. The `issuer` will be used as the `Keycloak URL`. * You can find this endpoint from the realm settings under the "General Tab" or visit [`http://localhost:8080/realms/my_realm_name/.well-known/openid-configuration`](http://localhost:8080/realms/my_realm_name/.well-known/openid-configuration) ![Add a Keycloak Realm.](/docs/img/guides/auth-keycloak/keycloak-create-realm.png) ## Create a Keycloak client The "Client ID" of the created client will serve as the `client_id` when you make API calls to authenticate the user. ![Add a Keycloak client](/docs/img/guides/auth-keycloak/keycloak-add-client.png) ## Client settings After you've created the client successfully, ensure that you set the following settings: 1. The "Client Protocol" should be set to `openid-connect`. 2. The "Access Type" should be set to "confidential". 3. The "Valid Redirect URIs" should be set to: `https://.supabase.co/auth/v1/callback`. ![Obtain the client id, set the client protocol and access type](/docs/img/guides/auth-keycloak/keycloak-client-id.png) ![Set redirect uri](/docs/img/guides/auth-keycloak/keycloak-redirect-uri.png) ## Obtain the client secret This will serve as the `client_secret` when you make API calls to authenticate the user. Under the "Credentials" tab, the `Secret` value will be used as the `client secret`. ![Obtain the client secret](/docs/img/guides/auth-keycloak/keycloak-client-secret.png) ## Add login code to your client app Since Keycloak version 22, the `openid` scope must be passed. Add this to the [`supabase.auth.signInWithOAuth()`](/docs/reference/javascript/auth-signinwithoauth) method. ## Resources * You can find the Keycloak OpenID endpoint configuration under the realm settings. ![Keycloak OpenID Endpoint Configuration](/docs/img/guides/auth-keycloak/keycloak-openid-endpoint-config.png) # Login with LinkedIn To enable LinkedIn Auth for your project, you need to set up a LinkedIn OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up LinkedIn logins for your application consists of 3 parts: * Create and configure a LinkedIn Project and App on the [LinkedIn Developer Dashboard](https://www.linkedin.com/developers/apps). * Add your *LinkedIn (OIDC)* `client_id` and `client_secret` to your [Supabase Project](https://supabase.com/dashboard). * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js). ## Access your LinkedIn Developer account * Go to [LinkedIn Developer Dashboard](https://www.linkedin.com/developers/apps). * Log in (if necessary.) ![LinkedIn Developer Portal](/docs/img/guides/auth-linkedin/linkedin_developers_page.png) ## Find your callback URL ## Create a LinkedIn OAuth app * Go to [LinkedIn Developer Dashboard](https://www.linkedin.com/developers/apps). * Click on `Create App` at the top right * Enter your `LinkedIn Page` and `App Logo` * Save your app * Click `Products` from the top menu * Look for `Sign In with LinkedIn using OpenID Connect` and click on Request Access * Click `Auth` from the top menu * Add your `Redirect URL` to the `Authorized Redirect URLs for your app` section * Copy and save your newly-generated `Client ID` * Copy and save your newly-generated `Client Secret` Ensure that the appropriate scopes have been added under OAuth 2.0 Scopes at the bottom of the `Auth` screen. ![Required OAuth 2.0 Scopes](/docs/img/guides/auth-linkedin/oauth-scopes.png) ## Enter your LinkedIn (OIDC) credentials into your Supabase project ## Add login code to your client app ## LinkedIn Open ID Connect (OIDC) We will be replacing the *LinkedIn* provider with a new *LinkedIn (OIDC)* provider to support recent changes to the LinkedIn [OAuth APIs](https://learn.microsoft.com/en-us/linkedin/shared/authentication/authorization-code-flow?context=linkedin%2Fcontext\&tabs=HTTPS1). The new provider utilizes the [Open ID Connect standard](https://learn.microsoft.com/en-us/linkedin/consumer/integrations/self-serve/sign-in-with-linkedin-v2#validating-id-tokens). In view of this change, we have disabled edits on the *LinkedIn* provider and will be removing it effective 4th January 2024. Developers with LinkedIn OAuth Applications created prior to 1st August 2023 should create a new OAuth application [via the steps outlined above](/docs/guides/auth/social-login/auth-linkedin#create-a-linkedin-oauth-app) and migrate their credentials from the *LinkedIn* provider to the *LinkedIn (OIDC)* provider. Alternatively, you can also head to the `Products` section and add the newly release`Sign In with LinkedIn using OpenID Connect` to your existing OAuth application. Developers using the Supabase CLI to test their LinkedIn OAuth application should also update their `config.toml` to make use of the new provider: [auth.external.linkedin_oidc] enabled = true client_id = ... secret = ... Do reach out to support if you have any concerns around this change. ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [LinkedIn Developer Dashboard](https://api.LinkedIn.com/apps) # Login with Notion To enable Notion Auth for your project, you need to set up a Notion Application and add the Application OAuth credentials to your Supabase Dashboard. ## Overview Setting up Notion logins for your application consists of 3 parts: * Create and configure a Notion Application [Notion Developer Portal](https://www.notion.so/my-integrations) * Retrieve your OAuth client ID and OAuth client secret and add them to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Create your notion integration * Go to [developers.notion.com](https://developers.notion.com/). * Click "View my integrations" and login. ![notion.so](/docs/img/guides/auth-notion/notion.png) * Once logged in, go to [notion.so/my-integrations](https://notion.so/my-integrations) and create a new integration. * When creating your integration, ensure that you select "Public integration" under "Integration type" and "Read user information including email addresses" under "Capabilities". * You will need to add a redirect URI, see [Add the redirect URI](#add-the-redirect-uri) * Once you've filled in the necessary fields, click "Submit" to finish creating the integration. ![notion.so](/docs/img/guides/auth-notion/notion-developer.png) ## Add the redirect URI * After selecting "Public integration", you should see an option to add "Redirect URIs". ![notion.so](/docs/img/guides/auth-notion/notion-redirect-uri.png) ## Add your Notion credentials into your Supabase project * Once you've created your notion integration, you should be able to retrieve the "OAuth client ID" and "OAuth client secret" from the "OAuth Domain and URIs" tab. ![notion.so](/docs/img/guides/auth-notion/notion-creds.png) ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Notion Account](https://notion.so) * [Notion Developer Portal](https://www.notion.so/my-integrations) # Login with Slack To enable Slack Auth for your project, you need to set up a Slack OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up Slack logins for your application consists of 3 parts: * Create and configure a Slack Project and App on the [Slack Developer Dashboard](https://api.slack.com/apps). * Add your Slack `API Key` and `API Secret Key` to your [Supabase Project](https://supabase.com/dashboard). * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js). ## Access your Slack Developer account * Go to [api.slack.com](https://api.slack.com/apps). * Click on `Your Apps` at the top right to log in. ![Slack Developer Portal.](/docs/img/guides/auth-slack/slack-portal.png) ## Find your callback URL ## Create a Slack OAuth app * Go to [api.slack.com](https://api.slack.com/apps). * Click on `Create New App` Under `Create an app...`: * Click `From scratch` * Type the name of your app * Select your `Slack Workspace` * Click `Create App` Under `App Credentials`: * Copy and save your newly-generated `Client ID` * Copy and save your newly-generated `Client Secret` Under the sidebar, select `OAuth & Permissions` and look for `Redirect URLs`: * Click `Add New Redirect URL` * Paste your `Callback URL` then click `Add` * Click `Save URLs` Under `Scopes`: * Add the following scopes under the `User Token Scopes`: `profile`, `email`, `openid`. These scopes are the default scopes that Supabase Auth uses to request for user information. Do not add other scopes as [Sign In With Slack only supports `profile`, `email`, `openid`](https://api.slack.com/authentication/sign-in-with-slack#request). ## Enter your Slack credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Slack Developer Dashboard](https://api.slack.com/apps) # Login with Spotify To enable Spotify Auth for your project, you need to set up a Spotify OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up Spotify logins for your application consists of 3 parts: * Create and configure a Spotify Project and App on the [Spotify Developer Dashboard](https://developer.spotify.com/dashboard/). * Add your Spotify `API Key` and `API Secret Key` to your [Supabase Project](https://supabase.com/dashboard). * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js). ## Access your Spotify Developer account * Log into [Spotify](https://spotify.com) * Access the [Spotify Developer Dashboard](https://developer.spotify.com/dashboard) ![Spotify Developer Portal.](/docs/img/guides/auth-spotify/spotify-portal.png) ## Find your callback URL ## Create a Spotify OAuth app * Log into [Spotify](https://spotify.com). * Go to the [Spotify Developer Dashboard](https://developer.spotify.com/dashboard) * Click `Create an App` * Type your `App name` * Type your `App description` * Check the box to agree with the `Developer TOS and Branding Guidelines` * Click `Create` * Save your `Client ID` * Save your `Client Secret` * Click `Edit Settings` Under `Redirect URIs`: * Paste your Supabase Callback URL in the box * Click `Add` * Click `Save` at the bottom ## Enter your Spotify credentials into your Supabase project ## Add login code to your client app The following outlines the steps to sign in using Spotify with Supabase Auth. 1. Call the signin method from the client library. 2. The user is redirected to the Spotify login page. 3. After completing the sign-in process, the user will be redirected to your app with an error that says the email address needs to be confirmed. Simultaneously the user receives a confirmation email from Supabase Auth. 4. The user clicks the confirmation link in the email. 5. The user is brought back to the app and is now signed in. ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Spotify Developer Dashboard](https://developer.spotify.com/dashboard/) # Login with Twitch To enable Twitch Auth for your project, you need to set up a Twitch Application and add the Application OAuth credentials to your Supabase Dashboard. ## Overview Setting up Twitch logins for your application consists of 3 parts: * Create and configure a Twitch Application [Twitch Developer Console](https://dev.twitch.tv/console) * Add your Twitch OAuth Consumer keys to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Access your Twitch Developer account * Go to [dev.twitch.tv](https://dev.twitch.tv). * Click on `Log in with Twitch` at the top right to log in. * If you have not already enabled 2-Factor Authentication for your Twitch Account, you will need to do that at [Twitch Security Settings](https://www.twitch.tv/settings/security) before you can continue. ![Twitch Developer Page](/docs/img/guides/auth-twitch/twitch-developer-page.png) * Once logged in, go to the [Twitch Developer Console](https://dev.twitch.tv/console). ![Twitch Developer Console](/docs/img/guides/auth-twitch/twitch-console.png) ## Find your callback URL ## Create a Twitch application ![Twitch Developer Console](/docs/img/guides/auth-twitch/twitch-console.png) * Click on `+ Register Your Application` at the top right. ![Register Application](/docs/img/guides/auth-twitch/twitch-register-your-application.png) * Enter the name of your application. * Type or paste your `OAuth Redirect URL` (the callback URL from the previous step.) * Select a category for your app. * Check the CAPTCHA box and click `Create`. ## Retrieve your Twitch OAuth client ID and client secret * Click `Manage` at the right of your application entry in the list. ![Twitch Applications List](/docs/img/guides/auth-twitch/twitch-applications-list.png) * Copy your Client ID. * Click `New Secret` to create a new Client Secret. * Copy your Client Secret. ![Get Client ID and Secret](/docs/img/guides/auth-twitch/twitch-get-keys.png) ## Add your Twitch credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Twitch Account](https://twitch.tv) * [Twitch Developer Console](https://dev.twitch.tv/console) # Login with Twitter To enable Twitter Auth for your project, you need to set up a Twitter OAuth application and add the application credentials in the Supabase Dashboard. ## Overview Setting up Twitter logins for your application consists of 3 parts: * Create and configure a Twitter Project and App on the [Twitter Developer Dashboard](https://developer.twitter.com/en/portal/dashboard). * Add your Twitter `API Key` and `API Secret Key` to your [Supabase Project](https://supabase.com/dashboard). * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js). ## Access your Twitter Developer account * Go to [developer.twitter.com](https://developer.twitter.com). * Click on `Sign in` at the top right to log in. ![Twitter Developer Portal.](/docs/img/guides/auth-twitter/twitter-portal.png) ## Find your callback URL ## Create a Twitter OAuth app * Click `+ Create Project`. * Enter your project name, click `Next`. * Select your use case, click `Next`. * Enter a description for your project, click `Next`. * Enter a name for your app, click `Next`. * Copy and save your `API Key` (this is your `client_id`). * Copy and save your `API Secret Key` (this is your `client_secret`). * Click on `App settings` to proceed to next steps. * At the bottom, you will find `User authentication settings`. Click on `Set up`. * Under `User authentication settings`, you can configure `App permissions`. * Make sure you turn ON `Request email from users`. * Select `Web App...` as the `Type of App`. * Under `App info` configure the following. * Enter your `Callback URL`. Check the **Find your callback URL** section above to learn how to obtain your callback URL. * Enter your `Website URL` (tip: try `http://127.0.0.1:port` or `http://www.localhost:port` during development) * Enter your `Terms of service URL`. * Enter your `Privacy policy URL`. * Click `Save`. ## Enter your Twitter credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Twitter Developer Dashboard](https://developer.twitter.com/en/portal/dashboard) # SSO and Social Login with WorkOS ## Use Social Login with WorkOS ### Step 1. Create a WorkOS organization Log in to the WorkOS dashboard and visit the Organizations tab to create an organization. ![Create an Organization](/docs/img/guides/auth-workos/workos-create-organization.png) Alternatively, you can [create an organization via the WorkOS API](https://workos.com/docs/reference/organization/create). ## Step 2. Obtain your `Client ID` and `WORKOS_API_KEY` values ![Get your Environment's Client ID and Secret](/docs/img/guides/auth-workos/workos-dashboard-get-client-id-and-key.png) Visit the getting started page of the [WorkOS Dashboard](https://dashboard.workos.com/get-started). Copy the following values from the Quickstart panel: * `WORKOS_CLIENT_ID` * `WORKOS_API_KEY` ## Step 3. Add your WorkOS credentials to your Supabase project ![Enter your WorkOS application details in your Supabase app's auth provider settings panel](/docs/img/guides/auth-workos/supabase-workos-configuration.png) 1. Go to your Supabase Project Dashboard. 2. In the left sidebar, click the Authentication icon (near the top). 3. Click on Providers under the Configuration section. 4. Click on WorkOS from the accordion list to expand. 5. Toggle the `WorkOS Enabled` switch to ON. 6. Enter `https://api.workos.com` in the WorkOS URL field. 7. Enter your WorkOS Client ID and WorkOS Client Secret saved in the previous step. 8. Copy the `Callback URL (for OAuth)` value from the form and save it somewhere handy. 9. Click Save. ## Step 4. Set your Supabase redirect URI in the WorkOS Dashboard Visit the WorkOS dashboard and click the redirects button in the left navigation panel. On the redirects page, enter your Supabase project's `Callback URL (for OAuth)` which you saved in the previous step, as shown below: ![Set your Supbase project redirect URL in the WorkOS dashboard](/docs/img/guides/auth-workos/workos-set-supabase-redirect.png) ## Step 5. Add login code to your client app When a user signs in, call `signInWithOAuth` with `workos` as the provider. ```javascript import { createClient } from '@supabase/supabase-js'; const supabase = createClient('', ''); const redirect = (url: string) => {} // ---cut--- async function signInWithWorkOS() { const { data, error } = await supabase.auth.signInWithOAuth({ provider: 'workos', options: { redirectTo: 'http://example.com/auth/v1/callback', // Make sure your redirect URL is configured in the Supabase Dashboard Auth settings queryParams: { connection: '', }, }, }) if (data.url) { redirect(data.url) // use the redirect API for your server or framework } } ``` Within your specified callback URL, you'll exchange the code for a logged-in user profile: ```javascript auth/v1/callback/route.ts import { NextResponse } from 'next/server' import { createClient } from '@/utils/supabase/server' export async function GET(request: Request) { const { searchParams, origin } = new URL(request.url) const code = searchParams.get('code') // if "next" is in param, use it as the redirect URL const next = searchParams.get('next') ?? '/' if (code) { const supabase = await createClient() const { error } = await supabase.auth.exchangeCodeForSession(code) if (!error) { const forwardedHost = request.headers.get('x-forwarded-host') // original origin before load balancer const isLocalEnv = process.env.NODE_ENV === 'development' if (isLocalEnv) { // we can be sure that there is no load balancer in between, so no need to watch for X-Forwarded-Host return NextResponse.redirect(`${origin}${next}`) } else if (forwardedHost) { return NextResponse.redirect(`https://${forwardedHost}${next}`) } else { return NextResponse.redirect(`${origin}${next}`) } } } // return the user to an error page with instructions return NextResponse.redirect(`${origin}/auth/auth-code-error`) } ``` ## Resources * [WorkOS Documentation](https://workos.com/docs/sso/guide) # Login with Zoom To enable Zoom Auth for your project, you need to set up a Zoom OAuth application and add the application credentials to your Supabase Dashboard. ## Overview Setting up Zoom logins for your application consists of 3 parts: * Create and configure a Zoom OAuth App on [Zoom App Marketplace](https://marketplace.zoom.us/) * Add your Zoom OAuth keys to your [Supabase Project](https://supabase.com/dashboard) * Add the login code to your [Supabase JS Client App](https://github.com/supabase/supabase-js) ## Access your Zoom Developer account * Go to [marketplace.zoom.us](https://marketplace.zoom.us/). * Click on `Sign In` at the top right to log in. ![Zoom Developer Portal.](/docs/img/guides/auth-zoom/zoom-portal.png) ## Find your callback URL ## Create a Zoom OAuth app * Go to [marketplace.zoom.us](https://marketplace.zoom.us/). * Click on `Sign In` at the top right to log in. * Click `Build App` (from the dropdown Develop) * In the OAuth card, click `Create` * Type the name of your app * Choose app type * Click `Create` Under `App credentials` * Copy and save your `Client ID`. * Copy and save your `Client secret`. * Add your `Callback URL` in the OAuth allow list. Under `Redirect URL for OAuth` * Paste your `Callback URL` Under `Scopes` * Click on `Add scopes` * Click on `User` * Choose `user:read` * Click `Done` * Click `Continue` ## Enter your Zoom credentials into your Supabase project ## Add login code to your client app ## Resources * [Supabase - Get started for free](https://supabase.com) * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Zoom App Marketplace](https://marketplace.zoom.us/) # Auth0 Use Auth0 with your Supabase project Auth0 can be used as a third-party authentication provider alongside Supabase Auth, or standalone, with your Supabase project. ## Getting started 1. First you need to add an integration to connect your Supabase project with your Auth0 tenant. You will need your tenant ID (and in some cases region ID). 2. Add a new Third-party Auth integration in your project's [Authentication settings](/dashboard/project/_/settings/auth). 3. Assign the `role: 'authenticated'` custom claim to all JWTs by using an Auth0 Action. 4. Finally setup the Supabase client in your application. ## Setup the Supabase client library ## Add a new Third-Party Auth integration to your project In the dashboard navigate to your project's [Authentication settings](/dashboard/project/_/settings/auth) and find the Third-Party Auth section to add a new integration. In the CLI add the following config to your `supabase/config.toml` file: ```toml [auth.third_party.auth0] enabled = true tenant = "" tenant_region = "" # if your tenant has a region ``` ## Use an Auth0 Action to assign the authenticated role Your Supabase project inspects the `role` claim present in all JWTs sent to it, to assign the correct Postgres role when using the Data API, Storage or Realtime authorization. By default, Auth0 JWTs (both access token and ID token) do not contain a `role` claim in them. If you were to send such a JWT to your Supabase project, the `anon` role would be assigned when executing the Postgres query. Most of your app's logic will be accessible by the `authenticated` role. A recommended approach to do this is to configure the [`onExecutePostLogin` Auth0 Action](https://auth0.com/docs/secure/tokens/json-web-tokens/create-custom-claims#create-custom-claims) which will add the custom claim: ```javascript exports.onExecutePostLogin = async (event, api) => { api.accessToken.setCustomClaim('role', 'authenticated') } ``` ## Limitations At this time, Auth0 tenants with the following [signing algorithms](https://auth0.com/docs/get-started/applications/signing-algorithms) are not supported: * HS256 (HMAC with SHA-256) -- also known as symmetric JWTs * PS256 (RSA-PSS with SHA-256) # Amazon Cognito (Amplify) Use Amazon Cognito via Amplify or standalone with your Supabase project Amazon Cognito User Pools (via AWS Amplify or on its own) can be used as a third-party authentication provider alongside Supabase Auth, or standalone, with your Supabase project. ## Getting started 1. First you need to add an integration to connect your Supabase project with your Amazon Cognito User Pool. You will need the pool's ID and region. 2. Add a new Third-party Auth integration in your project's [Authentication settings](/dashboard/project/_/settings/auth) or configure it in the CLI. 3. Assign the `role: 'authenticated'` custom claim to all JWTs by using a Pre-Token Generation Trigger. 4. Finally setup the Supabase client in your application. ## Setup the Supabase client library ## Add a new Third-Party Auth integration to your project In the dashboard navigate to your project's [Authentication settings](/dashboard/project/_/settings/auth) and find the Third-Party Auth section to add a new integration. In the CLI add the following config to your `supabase/config.toml` file: ```toml [auth.third_party.aws_cognito] enabled = true user_pool_id = "" user_pool_region = "" ``` ## Use a pre-token generation trigger to assign the authenticated role Your Supabase project inspects the `role` claim present in all JWTs sent to it, to assign the correct Postgres role when using the Data API, Storage or Realtime authorization. By default, Amazon Cognito JWTs (both ID token and access tokens) do not contain a `role` claim in them. If you were to send such a JWT to your Supabase project, the `anon` role would be assigned when executing the Postgres query. Most of your app's logic will be accessible by the `authenticated` role. A recommended approach to do this is to configure a [Pre-Token Generation Trigger](https://docs.aws.amazon.com/cognito/latest/developerguide/user-pool-lambda-pre-token-generation.html) either `V1_0` (ID token only) or `V2_0` (both access and ID token). To do this you will need to create a new Lambda function (in any language and runtime) and assign it to the [Amazon Cognito User Pool's Lambda Triggers configuration](https://docs.aws.amazon.com/cognito/latest/developerguide/cognito-user-identity-pools-working-with-aws-lambda-triggers.html). For example, the Lambda function should look similar to this: # Clerk Use Clerk with your Supabase project Clerk can be used as a third-party authentication provider alongside Supabase Auth, or standalone, with your Supabase project. ## Getting started Getting started is incredibly easy. Start off by visiting [Clerk's Connect with Supabase page](https://dashboard.clerk.com/setup/supabase) to configure your Clerk instance for Supabase compatibility. Finally add a [new Third-Party Auth integration with Clerk](/dashboard/project/_/auth/third-party) in the Supabase dashboard. ### Configure for local development or self-hosting When developing locally or self-hosting with the Supabase CLI, add the following config to your `supabase/config.toml` file: ```toml [auth.third_party.clerk] enabled = true domain = "example.clerk.accounts.dev" ``` You will still need to configure your Clerk instance for Supabase compatibility. ### Manually configuring your Clerk instance If you are not able to use [Clerk's Connect with Supabase page](https://dashboard.clerk.com/setup/supabase) to configure your Clerk instance for working with Supabase, follow these steps. 1. Add the `role` claim to [Clerk session tokens](https://clerk.com/docs/backend-requests/resources/session-tokens) by [customizing them](https://clerk.com/docs/backend-requests/custom-session-token). End-users who are authenticated should have the `authenticated` value for the claim. If you have an advanced Postgres setup where authenticated end-users use different Postgres roles to access the database, adjust the value to use the correct role name. 2. Once all Clerk session tokens for your instance contain the `role` claim, add a [new Third-Party Auth integration with Clerk](/dashboard/project/_/auth/third-party) in the Supabase dashboard or register it in the CLI as instructed above. ## Setup the Supabase client library ## Using RLS policies Once you've configured the Supabase client library to use Clerk session tokens, you can use RLS policies to secure access to your project's database, Storage objects and Realtime channels. The recommended way to design RLS policies with Clerk is to use claims present in your Clerk session token to allow or reject access to your project's data. Check [Clerk's docs](https://clerk.com/docs/backend-requests/resources/session-tokens) on the available JWT claims and their values. ### Example: Check user organization role ```sql create policy "Only organization admins can insert in table" on table_name for insert to authenticated with check ( ((select auth.jwt()->>'org_role') = 'org:admin') and (organization_id = (select auth.jwt()->>'org_id')) ); ``` This RLS policy checks that the newly inserted row in the table has the user's declared organization ID (from the `org_id` session token claim) in the `organization_id` column. Additionally it ensures that they're an `org:admin`. This way only organization admins can add rows to the table, for organizations they're a member of. ### Example: Check user has passed second factor verification ```sql create policy "Only users that have passed second factor verification can read from table" on table_name for select as restrictive to authenticated using ( ((select auth.jwt()->'fva'->>1) != '-1') ); ``` This example uses a restrictive RLS policy checks that the [second factor verification](https://clerk.com/docs/guides/reverification) age element in the `fva` claim is not `'-1'` indicating the user has passed through second factor verification. ## Deprecated integration with JWT templates As of 1st April 2025 the previously available [Clerk Integration with Supabase](https://supabase.com/partners/integrations/clerk) is considered deprecated and is no longer recommended for use. All projects using the deprecated integration will be excluded from Third-Party Monthly Active User (TP-MAU) charges until at least 1st January 2026. This integration used low-level primitives that are still available in Supabase and Clerk, such as a [configurable JWT secret](/dashboard/project/_/settings/api) and [JWT templates from Clerk](https://clerk.com/docs/backend-requests/jwt-templates). This enables you to keep using it in an unofficial manner, though only limited support will be provided from Supabase. Deprecation is done for the following reasons: * Sharing your project's JWT secret with a third-party is a problematic security practice * Rotating the project's JWT secret in this case almost always results in significant downtime for your application * Additional latency to [generate a new JWT](https://clerk.com/docs/backend-requests/jwt-templates#generate-a-jwt) for use with Supabase, instead of using the Clerk [session tokens](https://clerk.com/docs/backend-requests/resources/session-tokens) # Firebase Auth Use Firebase Auth with your Supabase project Firebase Auth can be used as a third-party authentication provider alongside Supabase Auth, or standalone, with your Supabase project. ## Getting started 1. First you need to add an integration to connect your Supabase project with your Firebase project. You will need to get the Project ID in the [Firebase Console](https://console.firebase.google.com/u/0/project/_/settings/general). 2. Add a new Third-party Auth integration in your project's [Authentication settings](/dashboard/project/_/settings/auth). 3. If you are using Third Party Auth when self hosting, create and attach restrictive RLS policies to all tables in your public schema, Storage and Realtime to **prevent unauthorized access from unrelated Firebase projects**. 4. Assign the `role: 'authenticated'` [custom user claim](https://firebase.google.com/docs/auth/admin/custom-claims) to all your users. 5. Finally set up the Supabase client in your application. ## Setup the Supabase client library ## Add a new Third-Party Auth integration to your project In the dashboard navigate to your project's [Authentication settings](/dashboard/project/_/settings/auth) and find the Third-Party Auth section to add a new integration. In the CLI add the following config to your `supabase/config.toml` file: ```toml [auth.third_party.firebase] enabled = true project_id = "" ``` ## Adding an extra layer of security to your project's RLS policies (self-hosting only) Firebase Auth uses a single set of JWT signing keys for all projects. This means that JWTs issued from an unrelated Firebase project to yours could access data in your Supabase project. When using the Supabase hosted platform, JWTs coming from Firebase project IDs you have not registered will be rejected before they reach your database. When self-hosting implementing this mechanism is your responsibility. An easy way to guard against this is to create and maintain the following RLS policies for **all of your tables in the `public` schema**. You should also attach this policy to [Storage](/docs/guides/storage/security/access-control) buckets or [Realtime](/docs/guides/realtime/authorization) channels. It's recommended you use a [restrictive Postgres Row-Level Security policy](https://www.postgresql.org/docs/current/sql-createpolicy.html). Restrictive RLS policies differ from regular (or permissive) policies in that they use the `as restrictive` clause when being defined. They do not grant permissions, but rather restrict any existing or future permissions. They're great for cases like this where the technical limitations of Firebase Auth remain separate from your app's logic. This is an example of such an RLS policy that will restrict access to only your project's (denoted with ``) users, and not any other Firebase project. ```sql create policy "Restrict access to Supabase Auth and Firebase Auth for project ID " on table_name as restrictive to authenticated using ( (auth.jwt()->>'iss' = 'https://.supabase.co/auth/v1') or ( auth.jwt()->>'iss' = 'https://securetoken.google.com/' and auth.jwt()->>'aud' = '' ) ); ``` If you have a lot of tables in your app, or need to manage complex RLS policies for [Storage](/docs/guides/storage) or [Realtime](/docs/guides/realtime) it can be useful to define a [stable Postgres function](https://www.postgresql.org/docs/current/xfunc-volatility.html) that performs the check to cut down on duplicate code. For example: ```sql create function public.is_supabase_or_firebase_project_jwt() returns bool language sql stable returns null on null input return ( (auth.jwt()->>'iss' = 'https://.supabase.co/auth/v1') or ( auth.jwt()->>'iss' = concat('https://securetoken.google.com/') and auth.jwt()->>'aud' = '' ) ); ``` Make sure you substitute `` with your Supabase project's ID and the `` to your Firebase Project ID. Then the restrictive policies on all your tables, buckets and channels can be simplified to be: ```sql create policy "Restrict access to correct Supabase and Firebase projects" on table_name as restrictive to authenticated using ((select public.is_supabase_or_firebase_project_jwt()) is true); ``` ## Assign the "role" custom claim Your Supabase project inspects the `role` claim present in all JWTs sent to it, to assign the correct Postgres role when using the Data API, Storage or Realtime authorization. By default, Firebase JWTs do not contain a `role` claim in them. If you were to send such a JWT to your Supabase project, the `anon` role would be assigned when executing the Postgres query. Most of your app's logic will be accessible by the `authenticated` role. ### Use Firebase Authentication functions to assign the authenticated role You have two choices to set up a Firebase Authentication function depending on your Firebase project's configuration: 1. Easiest: Use a [blocking Firebase Authentication function](https://firebase.google.com/docs/auth/extend-with-blocking-functions) but this is only available if your project uses [Firebase Authentication with Identity Platform](https://cloud.google.com/security/products/identity-platform). 2. Manually assign the custom claims to all users with the [admin SDK](https://firebase.google.com/docs/auth/admin/custom-claims#set_and_validate_custom_user_claims_via_the_admin_sdk) and define an [`onCreate` Firebase Authentication Cloud Function](https://firebase.google.com/docs/auth/extend-with-functions) to persist the role to all newly created users. Finally deploy your functions for the changes to take effect: firebase deploy --only functions Note that these functions are only called on new sign-ups and sign-ins. Existing users will not have these claims in their ID tokens. You will need to use the admin SDK to assign the role custom claim to all users. Make sure you do this after the blocking Firebase Authentication functions as described above are deployed. ### Use the admin SDK to assign the role custom claim to all users You need to run a script that will assign the `role: 'authenticated'` custom claim to all of your existing Firebase Authentication users. You can do this by combining the [list users](https://firebase.google.com/docs/auth/admin/manage-users#list_all_users) and [set custom user claims](https://firebase.google.com/docs/auth/admin/create-custom-tokens) admin APIs. An example script is provided below: ```javascript 'use strict'; const { initializeApp } = require('firebase-admin/app'); const { getAuth } = require('firebase-admin/auth'); initializeApp(); async function setRoleCustomClaim() => { let nextPageToken = undefined do { const listUsersResult = await getAuth().listUsers(1000, nextPageToken) nextPageToken = listUsersResult.pageToken await Promise.all(listUsersResult.users.map(async (userRecord) => { try { await getAuth().setCustomUserClaims(userRecord.id, { role: 'authenticated' }) } catch (error) { console.error('Failed to set custom role for user', userRecord.id) } }) } while (nextPageToken); }; setRoleCustomClaim().then(() => process.exit(0)) ``` After all users have received the `role: 'authenticated'` claim, it will appear in all newly issued ID tokens for the user. # Third-party auth First-class support for authentication providers Supabase has first-class support for these third-party authentication providers: * [Clerk](/docs/guides/auth/third-party/clerk) * [Firebase Auth](/docs/guides/auth/third-party/firebase-auth) * [Auth0](/docs/guides/auth/third-party/auth0) * [AWS Cognito (with or without AWS Amplify)](/docs/guides/auth/third-party/aws-cognito) You can use these providers alongside Supabase Auth, or on their own, to access the [Data API (REST and GraphQL)](/docs/guides/database), [Storage](/docs/guides/storage), [Realtime](/docs/guides/storage) and [Functions](/docs/guides/functions) from your existing apps. If you already have production apps using one of these authentication providers, and would like to use a Supabase feature, you no longer need to migrate your users to Supabase Auth or use workarounds like translating JWTs into the Supabase Auth format and using your project's signing secret. ## How does it work? To use Supabase products like Data APIs for your Postgres database, Storage or Realtime, you often need to send access tokens or JWTs via the Supabase client libraries or via the REST API. Third-party auth support means that when you add a new integration with one of these providers, the API will trust JWTs issued by the provider similar to how it trusts JWTs issued by Supabase Auth. This is made possible if the providers are using JWTs signed with asymmetric keys, which means that the Supabase APIs will be able to only verify but not create JWTs. ## Limitations There are some limitations you should be aware of when using third-party authentication providers with Supabase. 1. The third-party provider must use asymmetrically signed JWTs (exposed as an OIDC Issuer Discovery URL by the third-party authentication provider). Using symmetrically signed JWTs is not possible at this time. 2. The JWT signing keys from the third-party provider are stored in the configuration of your project, and are checked for changes periodically. If you are rotating your keys (when supported) allow up to 30 minutes for the change to be picked up. 3. It is not possible to disable Supabase Auth at this time. ## Pricing For a detailed breakdown of how charges are calculated, refer to [Manage Monthly Active Third-Party Users usage](/docs/guides/platform/manage-your-usage/monthly-active-users-third-party). # Users A **user** in Supabase Auth is someone with a user ID, stored in the Auth schema. Once someone is a user, they can be issued an Access Token, which can be used to access Supabase endpoints. The token is tied to the user, so you can restrict access to resources via [RLS policies](/docs/guides/database/postgres/row-level-security). ## Permanent and anonymous users Supabase distinguishes between permanent and anonymous users. * **Permanent users** are tied to a piece of Personally Identifiable Information (PII), such as an email address, a phone number, or a third-party identity. They can use these identities to sign back into their account after signing out. * **Anonymous users** aren't tied to any identities. They have a user ID and a personalized Access Token, but they have no way of signing back in as the same user if they are signed out. Anonymous users are useful for: * E-commerce applications, to create shopping carts before checkout * Full-feature demos without collecting personal information * Temporary or throw-away accounts See the [Anonymous Signins guide](/docs/guides/auth/auth-anonymous) to learn more about anonymous users. ## The user object The user object stores all the information related to a user in your application. The user object can be retrieved using one of these methods: 1. [`supabase.auth.getUser()`](/docs/reference/javascript/auth-getuser) 2. Retrieve a user object as an admin using [`supabase.auth.admin.getUserById()`](/docs/reference/javascript/auth-admin-listusers) A user can sign in with one of the following methods: * Password-based method (with email or phone) * Passwordless method (with email or phone) * OAuth * SAML SSO An identity describes the authentication method that a user can use to sign in. A user can have multiple identities. These are the types of identities supported: * Email * Phone * OAuth * SAML The user object contains the following attributes: | Attributes | Type | Description | | ------------------ | ---------------- | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | id | `string` | The unique id of the identity of the user. | | aud | `string` | The audience claim. | | role | `string` | The role claim used by Postgres to perform Row Level Security (RLS) checks. | | email | `string` | The user's email address. | | email\_confirmed\_at | `string` | The timestamp that the user's email was confirmed. If null, it means that the user's email is not confirmed. | | phone | `string` | The user's phone number. | | phone\_confirmed\_at | `string` | The timestamp that the user's phone was confirmed. If null, it means that the user's phone is not confirmed. | | confirmed\_at | `string` | The timestamp that either the user's email or phone was confirmed. If null, it means that the user does not have a confirmed email address and phone number. | | last\_sign\_in\_at | `string` | The timestamp that the user last signed in. | | app\_metadata | `object` | The `provider` attribute indicates the first provider that the user used to sign up with. The `providers` attribute indicates the list of providers that the user can use to login with. | | user\_metadata | `object` | Defaults to the first provider's identity data but can contain additional custom user metadata if specified. Refer to [**User Identity**](/docs/guides/auth/auth-identity-linking#the-user-identity) for more information about the identity object. | | identities | `UserIdentity[]` | Contains an object array of identities linked to the user. | | created\_at | `string` | The timestamp that the user was created. | | updated\_at | `string` | The timestamp that the user was last updated. | | is\_anonymous | `boolean` | Is true if the user is an anonymous user. | ## Resources * [User Management guide](/docs/guides/auth/managing-user-data) # Local Dev with CLI Developing locally using the Supabase CLI. You can use the Supabase CLI to run the entire Supabase stack locally on your machine, by running `supabase init` and then `supabase start`. To install the CLI, see the [installation guide](/docs/guides/cli/getting-started#installing-the-supabase-cli). The Supabase CLI provides tools to develop your project locally, deploy to the Supabase Platform, handle database migrations, and generate types directly from your database schema. ## Resources # Cron Schedule Recurring Jobs with Cron Syntax in Postgres Supabase Cron is a Postgres Module that simplifies scheduling recurring Jobs with cron syntax and monitoring Job runs inside Postgres. Cron Jobs can be created via SQL or the Cron interface inside of Supabase Dashboard and can run anywhere from every second to once a year depending on your use case. Every Job can run SQL snippets or database functions with zero network latency or make an HTTP request, such as invoking a Supabase Edge Function, with ease. ## How does Cron work? Under the hood, Supabase Cron uses the [`pg_cron`](https://github.com/citusdata/pg_cron) Postgres database extension which is the scheduling and execution engine for your Jobs. The extension creates a `cron` schema in your database and all Jobs are stored on the `cron.job` table. Every Job's run and its status is recorded on the `cron.job_run_details` table. The Supabase Dashboard provides and interface for you to schedule Jobs and monitor Job runs. You can also do the same with SQL. ## Resources * [`pg_cron` GitHub Repository](https://github.com/citusdata/pg_cron) # Install Install the Supabase Cron Postgres Module to begin scheduling recurring Jobs. ## Uninstall Uninstall Supabase Cron by disabling the `pg_cron` extension: ```sql drop extension if exists pg_cron; ``` # Quickstart ## Schedule a job ## Edit a job ## Activate/Deactivate a job ## Unschedule a job ## Inspecting job runs ## Examples ### Delete data every week Delete old data every Saturday at 3:30AM (GMT): ```sql select cron.schedule ( 'saturday-cleanup', -- name of the cron job '30 3 * * 6', -- Saturday at 3:30AM (GMT) $$ delete from events where event_time < now() - interval '1 week' $$ ); ``` ### Run a vacuum every day Vacuum every day at 3:00AM (GMT): ```sql select cron.schedule('nightly-vacuum', '0 3 * * *', 'VACUUM'); ``` ### Call a database function every 5 minutes Create a [`hello_world()`](/docs/guides/database/functions?language=sql#simple-functions) database function and then call it every 5 minutes: ```sql select cron.schedule('call-db-function', '*/5 * * * *', 'SELECT hello_world()'); ``` ### Call a database stored procedure To use a stored procedure, you can call it like this: ```sql select cron.schedule('call-db-procedure', '*/5 * * * *', 'CALL my_procedure()'); ``` ### Invoke Supabase Edge Function every 30 seconds Make a POST request to a Supabase Edge Function every 30 seconds: ```sql select cron.schedule( 'invoke-function-every-half-minute', '30 seconds', $$ select net.http_post( url:='https://project-ref.supabase.co/functions/v1/function-name', headers:=jsonb_build_object('Content-Type','application/json', 'Authorization', 'Bearer ' || 'YOUR_ANON_KEY'), body:=jsonb_build_object('time', now() ), timeout_milliseconds:=5000 ) as request_id; $$ ); ``` ## Caution: Scheduling system maintenance Be extremely careful when setting up Jobs for system maintenance tasks as they can have unintended consequences. For instance, scheduling a command to terminate idle connections with `pg_terminate_backend(pid)` can disrupt critical background processes like nightly backups. Often, there is an existing Postgres setting, such as `idle_session_timeout`, that can perform these common maintenance tasks without the risk. Reach out to [Supabase Support](https://supabase.com/support) if you're unsure if that applies to your use case. # Working With Arrays Postgres supports flexible [array types](https://www.postgresql.org/docs/12/arrays.html). These arrays are also supported in the Supabase Dashboard and in the JavaScript API. ## Create a table with an array column Create a test table with a text array (an array of strings): ## Insert a record with an array value ## View the results ## Query array data Postgres uses 1-based indexing (e.g., `textarray[1]` is the first item in the array). ## Resources * [Supabase JS Client](https://github.com/supabase/supabase-js) * [Supabase - Get started for free](https://supabase.com) * [Postgres Arrays](https://www.postgresql.org/docs/15/arrays.html) # Connecting with Beekeeper Studio [`Beekeeper Studio Community`](https://www.beekeeperstudio.io/get-community) is a free GUI tool for interacting with databases. # Connect to your database Connect to Postgres from your frontend, backend, or serverless environment ## Quick summary How you connect to your database depends on where you're connecting from: * For frontend applications, use the [Data API](#data-apis-and-client-libraries) * For Postgres clients, use a connection string * For single sessions (for example, database GUIs) or Postgres native commands (for example, using client applications like [pg\_dump](https://www.postgresql.org/docs/current/app-pgdump.html) or specifying connections for [replication](/docs/guides/database/postgres/setup-replication-external)) use the [direct connection string](#direct-connection) if your environment supports IPv6 * For persistent clients, and support for both IPv4 and IPv6, use [Supavisor session mode](#supavisor-session-mode) * For temporary clients (for example, serverless or edge functions) use [Supavisor transaction mode](#supavisor-transaction-mode) ## Quickstarts ## Data APIs and client libraries The Data APIs allow you to interact with your database using REST or GraphQL requests. You can use these APIs to fetch and insert data from the frontend, as long as you have [RLS](/docs/guides/database/postgres/row-level-security) enabled. * [REST](/docs/guides/api) * [GraphQL](/docs/guides/graphql/api) For convenience, you can also use the Supabase client libraries, which wrap the Data APIs with a developer-friendly interface and automatically handle authentication: * [JavaScript](/docs/reference/javascript) * [Flutter](/docs/reference/dart) * [Swift](/docs/reference/swift) * [Python](/docs/reference/python) * [C#](/docs/reference/csharp) * [Kotlin](/docs/reference/kotlin) ## Direct connection The direct connection string 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. The connection string looks like this: postgresql://postgres:[YOUR-PASSWORD]@db.apbkobhfnmcqqzqeeqss.supabase.co:5432/postgres Get your project's direct string from the [Database Settings](/dashboard/project/_/settings/database) page: 1. Go to the `Settings` section. 2. Click `Database`. 3. Under `Connection string`, make sure `Display connection pooler` is unchecked. Copy the URI. ## Shared pooler Every Supabase project includes a free, shared connection pooler. This is ideal for persistent servers when IPv6 is not supported. ### Supavisor session mode The session mode connection string connects to your Postgres instance via a proxy. The connection string looks like this: postgres://postgres.apbkobhfnmcqqzqeeqss:[YOUR-PASSWORD]@aws-0-[REGION].pooler.supabase.com:5432/postgres Get your project's session mode string from the [Database Settings](/dashboard/project/_/settings/database) page: 1. Go to the `Settings` section. 2. Click `Database`. 3. Under `Connection string`, make sure `Display connection pooler` is checked and `Session mode` is selected. Copy the URI. ### Supavisor transaction mode The transaction mode connection string connects to your Postgres instance via a proxy which serves as a connection pooler. This is ideal for serverless or edge functions, which require many transient connections. The connection string looks like this: postgres://postgres.apbkobhfnmcqqzqeeqss:[YOUR-PASSWORD]@aws-0-[REGION].pooler.supabase.com:6543/postgres Get your project's transaction mode string from the [Database Settings](/dashboard/project/_/settings/database) page: 1. Go to the `Settings` section. 2. Click `Database`. 3. Under `Connection string`, make sure `Display connection pooler` is checked and `Transaction mode` is selected. Copy the URI. ## Dedicated pooler For paying customers, we provision a Dedicated Pooler ([PgBouncer](https://www.pgbouncer.org/)) that's co-located with your Postgres database. This will require you to connect with IPv6 or, if that's not an option, you can use the [IPv4 add-on](/docs/guides/platform/ipv4-address). The Dedicated Pooler ensures best performance and latency, while using up more of your project's compute resources. If your network supports IPv6 or you have the IPv4 add-on, we encourage you to use the Dedicated Pooler over the Shared Pooler. ## More about connection pooling Connection pooling improves database performance by reusing existing connections between queries. This reduces the overhead of establishing connections and improves scalability. You can use an application-side pooler or a server-side pooler (Supabase automatically provides one called Supavisor), depending on whether your backend is persistent or serverless. ### 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 a 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. 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 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: ![Connection Info and Certificate.](/docs/img/database/database-settings-ssl.png) ## Resources * [Connection management](/docs/guides/database/connection-management) # Serverless Drivers Connecting to your Postgres database in serverless environments. Supabase provides several options for connecting to your Postgres database from serverless environments. [supabase-js](/docs/reference/javascript/introduction) is an isomorphic JavaScript client that uses the [auto-generated REST API](/docs/guides/api) and therefore works in any environment that supports HTTPS connections. This API has a built-in [connection pooler](/docs/guides/database/connecting-to-postgres#connection-pooler) and can serve thousands of simultaneous requests, and therefore is ideal for Serverless workloads. ## Vercel Edge Functions Vercel's [Edge runtime](https://vercel.com/docs/functions/runtimes/edge-runtime) is built on top of the [V8 engine](https://v8.dev/), that provides a limited set of Web Standard APIs. ### Quickstart Choose one of these Vercel Deploy Templates which use our [Vercel Deploy Integration](https://vercel.com/integrations/supabase) to automatically configure your connection strings as environment variables on your Vercel project! ### Manual configuration In your [`Database Settings`](https://supabase.com/dashboard/project/_/settings/database), make sure `Use connection pooler` is checked and `Transaction` mode is selected, then copy the URI and save it as the `POSTGRES_URL` environment variable. Remember to replace the password placeholder with your actual database password and add the following suffix `?workaround=supabase-pooler.vercel`. ```txt .env.local POSTGRES_URL="postgres://postgres.cfcxynqnhdybqtbhjemm:[YOUR-PASSWORD]@aws-0-ap-southeast-1.pooler.supabase.com:6543/postgres?workaround=supabase-pooler.vercel" ``` ## Cloudflare Workers Cloudflare's Workers runtime also uses the [V8 engine](https://v8.dev/) but provides polyfills for a subset of Node.js APIs and [TCP Sockets API](https://developers.cloudflare.com/workers/runtime-apis/tcp-sockets/), giving you a couple of options: * [supabase-js](https://developers.cloudflare.com/workers/databases/native-integrations/supabase/) * [Postgres.js](https://github.com/porsager/postgres?tab=readme-ov-file#cloudflare-workers-support) * [node-postgres](https://developers.cloudflare.com/workers/tutorials/postgres/) ## Supabase Edge Functions Supabase Edge Functions uses the [Deno runtime](https://deno.com/) which has native support for TCP connections allowing you to choose your favorite client: * [supabase-js](/docs/guides/functions/connect-to-postgres#using-supabase-js) * [Deno Postgres driver](/docs/guides/functions/connect-to-postgres#using-a-postgres-client) * [Postgres.js](https://github.com/porsager/postgres) * [Drizzle](/docs/guides/functions/connect-to-postgres#using-drizzle) # Connection management 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): ![Connection Info and Certificate.](/docs/img/database/pool-size.png) 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 concurrent 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 ![client connection graph](/docs/img/database/grafana-connections.png) ### 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 username can be used to identify the source: | Role | API/Tool | | ---------------------------- | ------------------------------------------------------------------------- | | `supabase_admin` | Used by Supabase for monitoring and by Realtime | | `authenticator` | Data API (PostgREST) | | `supabase_auth_admin` | Auth | | `supabase_storage_admin` | Storage | | `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...) | # Customizing Postgres configs Each Supabase project is a pre-configured Postgres cluster. You can override some configuration settings to suit your needs. This is an advanced topic, and we don't recommend touching these settings unless it is necessary. ### Viewing settings To list all Postgres settings and their descriptions, run: ```sql select * from pg_settings; ``` ## Configurable settings ### User-context settings The [`pg_settings`](https://www.postgresql.org/docs/current/view-pg-settings.html) table's `context` column specifies the requirements for changing a setting. By default, those with a `user` context can be changed at the `role` or `database` level with [SQL](https://supabase.com/dashboard/project/_/sql/). To list all user-context settings, run: ```sql select * from pg_settings where context = 'user'; ``` As an example, the `statement_timeout` setting can be altered: ```sql alter database "postgres" set "statement_timeout" TO '60s'; ``` To verify the change, execute: ```sql show "statement_timeout"; ``` ### Superuser settings Some settings can only be modified by a superuser. Supabase pre-enables the [`supautils` extension](https://supabase.com/blog/roles-postgres-hooks#setting-up-the-supautils-extension), which allows the `postgres` role to retain certain superuser privileges. It enables modification of the below reserved configurations at the `role` level: | Setting | Description | | ------------------------------------ | ------------------------------------------------------------------------------------------------------------------------------------------------------------ | | `auto_explain.log_min_duration` | Logs query plans taking longer than this duration. | | `auto_explain.log_nested_statements` | Log nested statements' plans. | | `log_min_messages` | Minimum severity level of messages to log. | | `pg_net.ttl` | Sets how long the [pg\_net extension](/docs/guides/database/extensions/pg_net) saves responses | | `pg_net.batch_size` | Sets how many requests the [pg\_net extension](/docs/guides/database/extensions/pg_net) can make per second | | `pgaudit.*` | Configures the [PGAudit extension](https://supabase.com/docs/guides/database/extensions/pgaudit). The `log_parameter` is still restricted to protect secrets | | `pgrst.*` | [`PostgREST` settings](https://docs.postgrest.org/en/stable/references/configuration.html#db-aggregates-enabled) | | `plan_filter.*` | Configures the [pg\_plan\_filter extension](https://supabase.com/docs/guides/database/extensions/pg_plan_filter) | | `session_replication_role` | Sets the session's behavior for triggers and rewrite rules. | | `track_io_timing` | Collects timing statistics for database I/O activity. | For example, to enable `log_nested_statements` for the `postgres` role, execute: ```sql alter role "postgres" set "auto_explain.log_nested_statements" to 'on'; ``` To view the change: ```sql select rolname, rolconfig from pg_roles where rolname = 'postgres'; ``` ### CLI configurable settings While many Postgres parameters are configurable directly, some configurations can be changed with the Supabase CLI at the [`system`](https://www.postgresql.org/docs/current/config-setting.html#CONFIG-SETTING-SQL) level. #### CLI supported parameters The following parameters are available for overrides: 1. [effective\_cache\_size](https://www.postgresql.org/docs/current/runtime-config-query.html#GUC-EFFECTIVE-CACHE-SIZE) 2. [logical\_decoding\_work\_mem](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-LOGICAL-DECODING-WORK-MEM) (CLI only) 3. [maintenance\_work\_mem](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-MAINTENANCE-WORK-MEM) 4. [max\_connections](https://www.postgresql.org/docs/current/runtime-config-connection.html#GUC-MAX-CONNECTIONS) (CLI only) 5. [max\_locks\_per\_transaction](https://www.postgresql.org/docs/current/runtime-config-locks.html#GUC-MAX-LOCKS-PER-TRANSACTION) (CLI only) 6. [max\_parallel\_maintenance\_workers](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-MAX-PARALLEL-MAINTENANCE-WORKERS) 7. [max\_parallel\_workers\_per\_gather](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-MAX-PARALLEL-WORKERS-PER-GATHER) 8. [max\_parallel\_workers](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-MAX-PARALLEL-WORKERS) 9. [max\_replication\_slots](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-MAX-REPLICATION-SLOTS) (CLI only) 10. [max\_slot\_wal\_keep\_size](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-MAX-SLOT-WAL-KEEP-SIZE) (CLI only) 11. [max\_standby\_archive\_delay](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-MAX-STANDBY-ARCHIVE-DELAY) (CLI only) 12. [max\_standby\_streaming\_delay](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-MAX-STANDBY-STREAMING-DELAY) (CLI only) 13. [max\_wal\_size](https://www.postgresql.org/docs/current/runtime-config-wal.html#GUC-MAX-WAL-SIZE) (CLI only) 14. [max\_wal\_senders](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-MAX-WAL-SENDERS) (CLI only) 15. [max\_worker\_processes](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-MAX-WORKER-PROCESSES) (CLI only) 16. [session\_replication\_role](https://www.postgresql.org/docs/current/runtime-config-client.html#GUC-SESSION-REPLICATION-ROLE) 17. [shared\_buffers](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-SHARED-BUFFERS) (CLI only) 18. [statement\_timeout](https://www.postgresql.org/docs/current/runtime-config-client.html#GUC-STATEMENT-TIMEOUT) 19. [track\_activity\_query\_size](https://www.postgresql.org/docs/current/runtime-config-statistics.html#GUC-TRACK-ACTIVITY-QUERY-SIZE) 20. [track\_commit\_timestamp](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-TRACK-COMMIT-TIMESTAMP) 21. [wal\_keep\_size](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-WAL-KEEP-SIZE) (CLI only) 22. [wal\_sender\_timeout](https://www.postgresql.org/docs/current/runtime-config-replication.html#GUC-WAL-SENDER-TIMEOUT) (CLI only) 23. [work\_mem](https://www.postgresql.org/docs/current/runtime-config-resource.html#GUC-WORK-MEM) #### Managing Postgres configuration with the CLI To start: 1. [Install](/docs/guides/resources/supabase-cli) Supabase CLI 1.69.0+. 2. [Log in](/docs/guides/cli/local-development#log-in-to-the-supabase-cli) to your Supabase account using the CLI. To update Postgres configurations, use the [`postgres config`](/docs/reference/cli/supabase-postgres-config) command: ```bash supabase --experimental \ --project-ref \ postgres-config update --config shared_buffers=250MB ``` By default, the CLI will merge any provided config overrides with any existing ones. The `--replace-existing-overrides` flag can be used to instead force all existing overrides to be replaced with the ones being provided: ```bash supabase --experimental \ --project-ref \ postgres-config update --config max_parallel_workers=3 \ --replace-existing-overrides ``` To delete specific configuration overrides, use the `postgres-config delete` command: ```bash supabase --experimental \ --project-ref \ postgres-config delete --config shared_buffers,work_mem ``` By default, changing the configuration, whether by updating or deleting, causes the database and all associated read replicas to restart. You can use the `--no-restart` flag to prevent this behavior, and attempt to reload the updated configuration without a restart. Refer to the Postgres documentation to determine if a given parameter can be reloaded without a restart. ```bash supabase --experimental \ --project-ref \ postgres-config delete --config shared_buffers --no-restart ``` ### Resetting to default config To reset a setting to its default value at the database level: ```sql -- reset a single setting at the database level alter database "postgres" set "" to default; -- reset all settings at the database level alter database "postgres" reset all; ``` For `role` level configurations, you can run: ```sql alter role "" set "" to default; ``` ### Considerations 1. Changes through the CLI might restart the database causing momentary disruption to existing database connections; in most cases this should not take more than a few seconds. However, you can use the --no-restart flag to bypass the restart and keep the connections intact. Keep in mind that this depends on the specific configuration changes you're making. if the change requires a restart, using the --no-restart flag will prevent the restart but you won't see those changes take effect until a restart is manually triggered. Additionally, some parameters are required to be the same on Primary and Read Replicas; not restarting in these cases can result in read replica failure if the Primary/Read Replicas restart in isolation. 2. Custom Postgres Config will always override the default optimizations generated by Supabase. When changing compute add-ons, you should also review and update your custom Postgres Config to ensure they remain compatible and effective with the updated compute. 3. Some parameters (e.g. `wal_keep_size`) can increase disk utilization, triggering disk expansion, which in turn can lead to [increases in your bill](/docs/guides/platform/compute-add-ons#disk-io). # Connecting with DBeaver If you do not have DBeaver, you can download it from its [website](https://dbeaver.io/download/). # Debugging performance issues Debug slow-running queries using the Postgres execution planner. `explain()` is a method that provides the Postgres `EXPLAIN` execution plan of a query. It is a powerful tool for debugging slow queries and understanding how Postgres will execute a given query. This feature is applicable to any query, including those made through `rpc()` or write operations. ## Enabling `explain()` `explain()` is disabled by default to protect sensitive information about your database structure and operations. We recommend using `explain()` in a non-production environment. Run the following SQL to enable `explain()`: ```sql -- enable explain alter role authenticator set pgrst.db_plan_enabled to 'true'; -- reload the config notify pgrst, 'reload config'; ``` ## Using `explain()` To get the execution plan of a query, you can chain the `explain()` method to a Supabase query: ```ts const { data, error } = await supabase .from('instruments') .select() .explain() ``` ### Example data To illustrate, consider the following setup of a `instruments` table: ```sql create table instruments ( id int8 primary key, name text ); insert into books (id, name) values (1, 'violin'), (2, 'viola'), (3, 'cello'); ``` ### Expected response The response would typically look like this: ```markdown Aggregate (cost=33.34..33.36 rows=1 width=112) -> Limit (cost=0.00..18.33 rows=1000 width=40) -> Seq Scan on instruments (cost=0.00..22.00 rows=1200 width=40) ``` By default, the execution plan is returned in TEXT format. However, you can also retrieve it as JSON by specifying the `format` parameter. ## Production use with pre-request protection If you need to enable `explain()` in a production environment, ensure you protect your database by restricting access to the `explain()` feature. You can do so by using a pre-request function that filters requests based on the IP address: ```sql create or replace function filter_plan_requests() returns void as $$ declare headers json := current_setting('request.headers', true)::json; client_ip text := coalesce(headers->>'cf-connecting-ip', ''); accept text := coalesce(headers->>'accept', ''); your_ip text := '123.123.123.123'; -- replace this with your IP begin if accept like 'application/vnd.pgrst.plan%' and client_ip != your_ip then raise insufficient_privilege using message = 'Not allowed to use application/vnd.pgrst.plan'; end if; end; $$ language plpgsql; alter role authenticator set pgrst.db_pre_request to 'filter_plan_requests'; notify pgrst, 'reload config'; ``` Replace `'123.123.123.123'` with your actual IP address. ## Disabling explain To disable the `explain()` method after use, execute the following SQL commands: ```sql -- disable explain alter role authenticator set pgrst.db_plan_enabled to 'false'; -- if you used the above pre-request alter role authenticator set pgrst.db_pre_request to ''; -- reload the config notify pgrst, 'reload config'; ``` # Drizzle ### 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. # Postgres Extensions Overview Extensions are exactly as they sound - they "extend" the database with functionality which isn't part of the Postgres core. Supabase has pre-installed some of the most useful open source extensions. ### Enable and disable extensions ### Upgrade extensions If a new version of an extension becomes available on Supabase, you need to initiate a software upgrade in the [Infrastructure Settings](https://supabase.com/dashboard/project/_/settings/infrastructure) to access it. Software upgrades can also be initiated by restarting your server in the [General Settings](https://supabase.com/dashboard/project/_/settings/general). ### Full list of extensions Supabase is pre-configured with over 50 extensions. You can also install your own SQL extensions directly in the database through our SQL editor. # http: RESTful Client The `http` extension allows you to call RESTful endpoints within Postgres. ## Quick demo ## Overview Let's cover some basic concepts: * REST: stands for REpresentational State Transfer. It's a way to request data from external services. * RESTful APIs are servers which accept HTTP "calls". The calls are typically: * `GET` − Read only access to a resource. * `POST` − Creates a new resource. * `DELETE` − Removes a resource. * `PUT` − Updates an existing resource or creates a new resource. You can use the `http` extension to make these network requests from Postgres. ## Usage ### Enable the extension ### Available functions While the main usage is `http('http_request')`, there are 5 wrapper functions for specific functionality: * `http_get()` * `http_post()` * `http_put()` * `http_delete()` * `http_head()` ### Returned values A successful call to a web URL from the `http` extension returns a record with the following fields: * `status`: integer * `content_type`: character varying * `headers`: http\_header\[] * `content`: character varying. Typically you would want to cast this to `jsonb` using the format `content::jsonb` ## Examples ### Simple `GET` example ```sql select "status", "content"::jsonb from http_get('https://jsonplaceholder.typicode.com/todos/1'); ``` ### Simple `POST` example ```sql select "status", "content"::jsonb from http_post( 'https://jsonplaceholder.typicode.com/posts', '{ "title": "foo", "body": "bar", "userId": 1 }', 'application/json' ); ``` ## Resources * Official [`http` GitHub Repository](https://github.com/pramsey/pgsql-http) # HypoPG: Hypothetical indexes `HypoPG` is Postgres extension for creating hypothetical/virtual indexes. HypoPG allows users to rapidly create hypothetical/virtual indexes that have no resource cost (CPU, disk, memory) that are visible to the Postgres query planner. The motivation for HypoPG is to allow users to quickly search for an index to improve a slow query without consuming server resources or waiting for them to build. ## Enable the extension ### Speeding up a query Given the following table and a simple query to select from the table by `id`: ```sql create table account ( id int, address text ); insert into account(id, address) select id, id || ' main street' from generate_series(1, 10000) id; ``` We can generate an explain plan for a description of how the Postgres query planner intends to execute the query. ```sql explain select * from account where id=1; QUERY PLAN ------------------------------------------------------- Seq Scan on account (cost=0.00..180.00 rows=1 width=13) Filter: (id = 1) (2 rows) ``` Using HypoPG, we can create a hypothetical index on the `account(id)` column to check if it would be useful to the query planner and then re-run the explain plan. Note that the virtual indexes created by HypoPG are only visible in the Postgres connection that they were created in. Supabase connects to Postgres through a connection pooler so the `hypopg_create_index` statement and the `explain` statement should be executed in a single query. ```sql select * from hypopg_create_index('create index on account(id)'); explain select * from account where id=1; QUERY PLAN ------------------------------------------------------------------------------------ Index Scan using <13504>btree_account_id on hypo (cost=0.29..8.30 rows=1 width=13) Index Cond: (id = 1) (2 rows) ``` The query plan has changed from a `Seq Scan` to an `Index Scan` using the newly created virtual index, so we may choose to create a real version of the index to improve performance on the target query: ```sql create index on account(id); ``` ## Functions * [`hypo_create_index(text)`](https://hypopg.readthedocs.io/en/rel1_stable/usage.html#create-a-hypothetical-index): A function to create a hypothetical index. * [`hypopg_list_indexes`](https://hypopg.readthedocs.io/en/rel1_stable/usage.html#manipulate-hypothetical-indexes): A View that lists all hypothetical indexes that have been created. * [`hypopg()`](https://hypopg.readthedocs.io/en/rel1_stable/usage.html#manipulate-hypothetical-indexes): A function that lists all hypothetical indexes that have been created with the same format as `pg_index`. * [`hypopg_get_index_def(oid)`](https://hypopg.readthedocs.io/en/rel1_stable/usage.html#manipulate-hypothetical-indexes): A function to display the `create index` statement that would create the index. * [`hypopg_get_relation_size(oid)`](https://hypopg.readthedocs.io/en/rel1_stable/usage.html#manipulate-hypothetical-indexes): A function to estimate how large a hypothetical index would be. * [`hypopg_drop_index(oid)`](https://hypopg.readthedocs.io/en/rel1_stable/usage.html#manipulate-hypothetical-indexes): A function to remove a given hypothetical index by `oid`. * [`hypopg_reset()`](https://hypopg.readthedocs.io/en/rel1_stable/usage.html#manipulate-hypothetical-indexes): A function to remove all hypothetical indexes. ## Resources * Official [HypoPG documentation](https://hypopg.readthedocs.io/en/rel1_stable/) # index_advisor: query optimization [Index advisor](https://github.com/supabase/index_advisor) is a Postgres extension for recommending indexes to improve query performance. Features: * Supports generic parameters e.g. `$1`, `$2` * Supports materialized views * Identifies tables/columns obfuscated by views * Skips duplicate indexes `index_advisor` is accessible directly through Supabase Studio by navigating to the [Query Performance Report](/dashboard/project/_/advisors/query-performance) and selecting a query and then the "indexes" tab. ![Supabase Studio index\_advisor integration.](/docs/img/index_advisor_studio.png) Alternatively, you can use index\_advisor directly via SQL. For example: ```sql select * from index_advisor('select book.id from book where title = $1'); startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors ---------------------+--------------------+-------------------+------------------+-----------------------------------------------------+-------- 0.00 | 1.17 | 25.88 | 6.40 | {"CREATE INDEX ON public.book USING btree (title)"},| {} (1 row) ``` ## Installation To get started, enable index\_advisor by running ```sql create extension index_advisor; ``` ## API Index advisor exposes a single function `index_advisor(query text)` that accepts a query and searches for a set of SQL DDL `create index` statements that improve the query's execution time. The function's signature is: ```sql index_advisor(query text) returns table ( startup_cost_before jsonb, startup_cost_after jsonb, total_cost_before jsonb, total_cost_after jsonb, index_statements text[], errors text[] ) ``` ## Usage As a minimal example, the `index_advisor` function can be given a single table query with a filter on an unindexed column. ```sql create extension if not exists index_advisor cascade; create table book( id int primary key, title text not null ); select * from index_advisor('select book.id from book where title = $1'); startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors ---------------------+--------------------+-------------------+------------------+-----------------------------------------------------+-------- 0.00 | 1.17 | 25.88 | 6.40 | {"CREATE INDEX ON public.book USING btree (title)"},| {} (1 row) ``` and will return a row recommending an index on the unindexed column. More complex queries may generate additional suggested indexes: ```sql create extension if not exists index_advisor cascade; create table author( id serial primary key, name text not null ); create table publisher( id serial primary key, name text not null, corporate_address text ); create table book( id serial primary key, author_id int not null references author(id), publisher_id int not null references publisher(id), title text ); create table review( id serial primary key, book_id int references book(id), body text not null ); select * from index_advisor(' select book.id, book.title, publisher.name as publisher_name, author.name as author_name, review.body review_body from book join publisher on book.publisher_id = publisher.id join author on book.author_id = author.id join review on book.id = review.book_id where author.id = $1 and publisher.id = $2 '); startup_cost_before | startup_cost_after | total_cost_before | total_cost_after | index_statements | errors ---------------------+--------------------+-------------------+------------------+-----------------------------------------------------------+-------- 27.26 | 12.77 | 68.48 | 42.37 | {"CREATE INDEX ON public.book USING btree (author_id)", | {} "CREATE INDEX ON public.book USING btree (publisher_id)", "CREATE INDEX ON public.review USING btree (book_id)"} (3 rows) ``` ## Limitations * index\_advisor will only recommend single column, B-tree indexes. More complex indexes will be supported in future releases. * when a generic argument's type is not discernible from context, an error is returned in the `errors` field. To resolve those errors, add explicit type casting to the argument. e.g. `$1::int`. ## Resources * [`index_advisor`](https://github.com/supabase/index_advisor) repo # pg_cron: Schedule Recurring Jobs with Cron Syntax in Postgres See the [Supabase Cron docs](/docs/guides/cron). # pg_graphql: GraphQL for PostgreSQL [pg\_graphql](https://supabase.github.io/pg_graphql/) is Postgres extension for interacting with the database using [GraphQL](https://graphql.org) instead of SQL. The extension reflects a GraphQL schema from the existing SQL schema and exposes it through a SQL function, `graphql.resolve(...)`. This enables any programming language that can connect to Postgres to query the database via GraphQL with no additional servers, processes, or libraries. The `pg_graphql` resolve method is designed to interop with [PostgREST](https://postgrest.org/en/stable/index.html), the tool that underpins the Supabase API, such that the `graphql.resolve` function can be called via RPC to safely and performantly expose the GraphQL API over HTTP/S. For more information about how the SQL schema is reflected into a GraphQL schema, see the [pg\_graphql API docs](https://supabase.github.io/pg_graphql/api/). ## Enable the extension ## Usage Given a table ```sql create table "Blog"( id serial primary key, name text not null, description text ); insert into "Blog"(name) values ('My Blog'); ``` The reflected GraphQL schema can be queried immediately as ```sql select graphql.resolve($$ { blogCollection(first: 1) { edges { node { id, name } } } } $$); ``` returning the JSON ```json { "data": { "blogCollection": { "edges": [ { "node": { "id": 1 "name": "My Blog" } } ] } } } ``` Note that `pg_graphql` fully supports schema introspection so you can connect any GraphQL IDE or schema inspection tool to see the full set of fields and arguments available in the API. ## API * [`graphql.resolve`](https://supabase.github.io/pg_graphql/sql_interface/): A SQL function for executing GraphQL queries. ## Resources * Official [`pg_graphql` documentation](https://github.com/supabase/pg_graphql) # pg_hashids: Short UIDs [pg\_hashids](https://github.com/iCyberon/pg_hashids) provides a secure way to generate short, unique, non-sequential ids from numbers. The hashes are intended to be small, easy-to-remember identifiers that can be used to obfuscate data (optionally) with a password, alphabet, and salt. For example, you may wish to hide data like user IDs, order numbers, or tracking codes in favor of `pg_hashid`'s unique identifiers. ## Enable the extension ## Usage Suppose we have a table that stores order information, and we want to give customers a unique identifier without exposing the sequential `id` column. To do this, we can use `pg_hashid`'s `id_encode` function. ```sql create table orders ( id serial primary key, description text, price_cents bigint ); insert into orders (description, price_cents) values ('a book', 9095); select id, id_encode(id) as short_id, description, price_cents from orders; id | short_id | description | price_cents ----+----------+-------------+------------- 1 | jR | a book | 9095 (1 row) ``` To reverse the `short_id` back into an `id`, there is an equivalent function named `id_decode`. ## Resources * Official [pg\_hashids documentation](https://github.com/iCyberon/pg_hashids) # pg_jsonschema: JSON Schema Validation [JSON Schema](https://json-schema.org) is a language for annotating and validating JSON documents. [`pg_jsonschema`](https://github.com/supabase/pg_jsonschema) is a Postgres extension that adds the ability to validate PostgreSQL's built-in `json` and `jsonb` data types against JSON Schema documents. ## Enable the extension ## Functions * [`json_matches_schema(schema json, instance json)`](https://github.com/supabase/pg_jsonschema#api): Checks if a `json` *instance* conforms to a JSON Schema *schema*. * [`jsonb_matches_schema(schema json, instance jsonb)`](https://github.com/supabase/pg_jsonschema#api): Checks if a `jsonb` *instance* conforms to a JSON Schema *schema*. ## Usage Since `pg_jsonschema` exposes its utilities as functions, we can execute them with a select statement: ```sql select extensions.json_matches_schema( schema := '{"type": "object"}', instance := '{}' ); ``` `pg_jsonschema` is generally used in tandem with a [check constraint](https://www.postgresql.org/docs/current/ddl-constraints.html) as a way to constrain the contents of a json/b column to match a JSON Schema. ```sql create table customer( id serial primary key, ... metadata json, check ( json_matches_schema( '{ "type": "object", "properties": { "tags": { "type": "array", "items": { "type": "string", "maxLength": 16 } } } }', metadata ) ) ); -- Example: Valid Payload insert into customer(metadata) values ('{"tags": ["vip", "darkmode-ui"]}'); -- Result: -- INSERT 0 1 -- Example: Invalid Payload insert into customer(metadata) values ('{"tags": [1, 3]}'); -- Result: -- ERROR: new row for relation "customer" violates check constraint "customer_metadata_check" -- DETAIL: Failing row contains (2, {"tags": [1, 3]}). ``` ## Resources * Official [`pg_jsonschema` documentation](https://github.com/supabase/pg_jsonschema) # pg_net: Async Networking [pg\_net](https://github.com/supabase/pg_net/) enables Postgres to make asynchronous HTTP/HTTPS requests in SQL. It differs from the [`http`](https://supabase.com/docs/guides/database/extensions/http) extension in that it is asynchronous by default. This makes it useful in blocking functions (like triggers). It eliminates the need for servers to continuously poll for database changes and instead allows the database to proactively notify external resources about significant events. ## Enable the extension ## `http_get` Creates an HTTP GET request returning the request's ID. HTTP requests are not started until the transaction is committed. ### Signature \[#get-signature] ```sql net.http_get( -- url for the request url text, -- key/value pairs to be url encoded and appended to the `url` params jsonb default '{}'::jsonb, -- key/values to be included in request headers headers jsonb default '{}'::jsonb, -- the maximum number of milliseconds the request may take before being canceled timeout_milliseconds int default 2000 ) -- request_id reference returns bigint strict volatile parallel safe language plpgsql ``` ### Usage \[#get-usage] ```sql select net.http_get('https://news.ycombinator.com') as request_id; request_id ---------- 1 (1 row) ``` ## `http_post` Creates an HTTP POST request with a JSON body, returning the request's ID. HTTP requests are not started until the transaction is committed. The body's character set encoding matches the database's `server_encoding` setting. ### Signature \[#post-signature] ```sql net.http_post( -- url for the request url text, -- body of the POST request body jsonb default '{}'::jsonb, -- key/value pairs to be url encoded and appended to the `url` params jsonb default '{}'::jsonb, -- key/values to be included in request headers headers jsonb default '{"Content-Type": "application/json"}'::jsonb, -- the maximum number of milliseconds the request may take before being canceled timeout_milliseconds int default 2000 ) -- request_id reference returns bigint volatile parallel safe language plpgsql ``` ### Usage \[#post-usage] ```sql select net.http_post( url:='https://httpbin.org/post', body:='{"hello": "world"}'::jsonb ) as request_id; request_id ---------- 1 (1 row) ``` ## `http_delete` Creates an HTTP DELETE request, returning the request's ID. HTTP requests are not started until the transaction is committed. ### Signature \[#post-signature] ```sql net.http_delete( -- url for the request url text, -- key/value pairs to be url encoded and appended to the `url` params jsonb default '{}'::jsonb, -- key/values to be included in request headers headers jsonb default '{}'::jsonb, -- the maximum number of milliseconds the request may take before being canceled timeout_milliseconds int default 2000 ) -- request_id reference returns bigint strict volatile parallel safe language plpgsql security definer ``` ### Usage \[#delete-usage] ```sql select net.http_delete( 'https://dummy.restapiexample.com/api/v1/delete/2' ) as request_id; ---------- 1 (1 row) ``` ## Analyzing responses Waiting requests are stored in the `net.http_request_queue` table. Upon execution, they are deleted. ```sql CREATE UNLOGGED TABLE net.http_request_queue ( id bigint NOT NULL DEFAULT nextval('net.http_request_queue_id_seq'::regclass), method text NOT NULL, url text NOT NULL, headers jsonb NOT NULL, body bytea NULL, timeout_milliseconds integer NOT NULL ) ``` Once a response is returned, by default, it is stored for 6 hours in the `net._http_response` table. ```sql CREATE UNLOGGED TABLE net._http_response ( id bigint NULL, status_code integer NULL, content_type text NULL, headers jsonb NULL, content text NULL, timed_out boolean NULL, error_msg text NULL, created timestamp with time zone NOT NULL DEFAULT now() ) ``` The responses can be observed with the following query: ```sql select * from net._http_response; ``` The data can also be observed in the `net` schema with the [Supabase Dashboard's SQL Editor](https://supabase.com/dashboard/project/_/editor) ## Debugging requests ### Inspecting request data The [Postman Echo API](https://documenter.getpostman.com/view/5025623/SWTG5aqV) returns a response with the same body and content as the request. It can be used to inspect the data being sent. Sending a post request to the echo API ```sql select net.http_post( url := 'https://postman-echo.com/post', body := '{"key1": "value", "key2": 5}'::jsonb ) as request_id; ``` Inspecting the echo API response content to ensure it contains the right body ```sql select "content" from net._http_response where id = -- returns information about the request -- including the body sent: {"key": "value", "key": 5} ``` Alternatively, by wrapping a request in a [database function](https://supabase.com/docs/guides/database/functions), sent row data can be logged or returned for inspection and debugging. ```sql create or replace function debugging_example (row_id int) returns jsonb as $$ declare -- Store payload data row_data_var jsonb; begin -- Retrieve row data and convert to JSON select to_jsonb("".*) into row_data_var from "" where "".id = row_id; -- Initiate HTTP POST request to URL perform net.http_post( url := 'https://postman-echo.com/post', -- Use row data as payload body := row_data_var ) as request_id; -- Optionally Log row data or other data for inspection in Supabase Dashboard's Postgres Logs raise log 'Logging an entire row as JSON (%)', row_data_var; -- return row data to inspect return row_data_var; -- Handle exceptions here if needed exception when others then raise exception 'An error occurred: %', SQLERRM; end; $$ language plpgsql; -- calling function select debugging_example(); ``` ### Inspecting failed requests Finds all failed requests ```sql select * from net._http_response where "status_code" >= 400 or "error_msg" is not null order by "created" desc; ``` ## Configuration The extension is configured to reliably execute up to 200 requests per second. The response messages are stored for only 6 hours to prevent needless buildup. The default behavior can be modified by rewriting config variables. ### Get current settings ```sql select "name", "setting" from pg_settings where "name" like 'pg_net%'; ``` ### Alter settings Change variables: ```sql alter role "postgres" set pg_net.ttl to '24 hours'; alter role "postgres" set pg_net.batch_size to 500; ``` Then reload the settings and restart the `pg_net` background worker with: ```sql select net.worker_restart(); ``` ## Examples ### Invoke a Supabase Edge Function Make a POST request to a Supabase Edge Function with auth header and JSON body payload: ```sql select net.http_post( url:='https://project-ref.supabase.co/functions/v1/function-name', headers:='{"Content-Type": "application/json", "Authorization": "Bearer "}'::jsonb, body:='{"name": "pg_net"}'::jsonb ) as request_id; ``` ### Call an endpoint every minute with [pg\_cron](https://supabase.com/docs/guides/database/extensions/pgcron) The pg\_cron extension enables Postgres to become its own cron server. With it you can schedule regular calls with up to a minute precision to endpoints. ```sql select cron.schedule( 'cron-job-name', '* * * * *', -- Executes every minute (cron syntax) $$ -- SQL query select "net"."http_post"( -- URL of Edge function url:='https://project-ref.supabase.co/functions/v1/function-name', headers:='{"Authorization": "Bearer "}'::jsonb, body:='{"name": "pg_net"}'::jsonb ) as "request_id"; $$ ); ``` ### Execute pg\_net in a trigger Make a call to an external endpoint when a trigger event occurs. ```sql -- function called by trigger create or replace function () returns trigger language plpgSQL as $$ begin -- calls pg_net function net.http_post -- sends request to postman API perform "net"."http_post"( 'https://postman-echo.com/post'::text, jsonb_build_object( 'old_row', to_jsonb(old.*), 'new_row', to_jsonb(new.*) ), headers:='{"Content-Type": "application/json"}'::jsonb ) as request_id; return new; END $$; -- trigger for table update create trigger after update on for each row execute function (); ``` ### Send multiple table rows in one request ```sql with "selected_table_rows" as ( select -- Converts all the rows into a JSONB array jsonb_agg(to_jsonb(.*)) as JSON_payload from -- good practice to LIMIT the max amount of rows ) select net.http_post( url := 'https://postman-echo.com/post'::text, body := JSON_payload ) AS request_id FROM "selected_table_rows"; ``` More examples can be seen on the [Extension's GitHub page](https://github.com/supabase/pg_net/) ## Limitations * To improve speed and performance, the requests and responses are stored in [unlogged tables](https://pgpedia.info/u/unlogged-table.html), which are not preserved during a crash or unclean shutdown. * By default, response data is saved for only 6 hours * Can only make POST requests with JSON data. No other data formats are supported * Intended to handle at most 200 requests per second. Increasing the rate can introduce instability * Does not have support for PATCH/PUT requests * Can only work with one database at a time. It defaults to the `postgres` database. ## Resources * Source code: [github.com/supabase/pg\_net](https://github.com/supabase/pg_net/) * Official Docs: [github.com/supabase/pg\_net](https://github.com/supabase/pg_net/) # pg_plan_filter: Restrict Total Cost [`pg_plan_filter`](https://github.com/pgexperts/pg_plan_filter) is Postgres extension to block execution of statements where query planner's estimate of the total cost exceeds a threshold. This is intended to give database administrators a way to restrict the contribution an individual query has on database load. ## Enable the extension `pg_plan_filter` can be enabled on a per connection basis: ```sql load 'plan_filter'; ``` or for all connections: ```sql alter database some_db set session_preload_libraries = 'plan_filter'; ``` ## API `plan_filter.statement_cost_limit`: restricts the maximum total cost for executed statements `plan_filter.limit_select_only`: restricts to `select` statements Note that `limit_select_only = true` is not the same as read-only because `select` statements may modify data, for example, through a function call. ## Example To demonstrate total cost filtering, we'll compare how `plan_filter.statement_cost_limit` treats queries that are under and over its cost limit. First, we set up a table with some data: ```sql create table book( id int primary key ); -- CREATE TABLE insert into book(id) select * from generate_series(1, 10000); -- INSERT 0 10000 ``` Next, we can review the explain plans for a single record select, and a whole table select. ```sql explain select * from book where id =1; QUERY PLAN --------------------------------------------------------------------------- Index Only Scan using book_pkey on book (cost=0.28..2.49 rows=1 width=4) Index Cond: (id = 1) (2 rows) explain select * from book; QUERY PLAN --------------------------------------------------------- Seq Scan on book (cost=0.00..135.00 rows=10000 width=4) (1 row) ``` Now we can choose a `statement_cost_filter` value between the total cost for the single select (2.49) and the whole table select (135.0) so one statement will succeed and one will fail. ```sql load 'plan_filter'; set plan_filter.statement_cost_limit = 50; -- between 2.49 and 135.0 select * from book where id = 1; id ---- 1 (1 row) -- SUCCESS ``` ```sql select * from book; ERROR: plan cost limit exceeded HINT: The plan for your query shows that it would probably have an excessive run time. This may be due to a logic error in the SQL, or it maybe just a very costly query. Rewrite your query or increase the configuration parameter "plan_filter.statement_cost_limit". -- FAILURE ``` ## Resources * Official [`pg_plan_filter` documentation](https://github.com/pgexperts/pg_plan_filter) # pg_repack: Physical storage optimization and maintenance [pg\_repack](https://github.com/reorg/pg_repack) is a Postgres extension to remove bloat from tables and indexes, and optionally restore the physical order of clustered indexes. Unlike CLUSTER and VACUUM FULL, pg\_repack runs "online" and does not hold a exclusive locks on the processed tables that could prevent ongoing database operations. pg\_repack's efficiency is comparable to using CLUSTER directly. pg\_repack provides the following methods to optimize physical storage: * Online CLUSTER: ordering table data by cluster index in a non-blocking way * Ordering table data by specified columns * Online VACUUM FULL: packing rows only in a non-blocking way * Rebuild or relocate only the indexes of a table pg\_repack has 2 components, the database extension and a client-side CLI to control it. ## Requirements * A target table must have a PRIMARY KEY, or a UNIQUE total index on a NOT NULL column. * Performing a full-table repack requires free disk space about twice as large as the target table and its indexes. pg\_repack requires the Postgres superuser role by default. That role is not available to users on the Supabase platform. To avoid that requirement, use the `-k` or `--no-superuser-check` flags on every `pg_repack` CLI command. The first version of pg\_repack with full support for non-superuser repacking is 1.5.2. You can check the version installed on your Supabase instance using ```sql select default_version from pg_available_extensions where name = 'pg_repack'; ``` If pg\_repack is not present, or the version is < 1.5.2, [upgrade to the latest version](/docs/guides/platform/upgrading) of Supabase to gain access. ## Usage ### Enable the extension Get started with pg\_repack by enabling the extension in the Supabase Dashboard. ### Install the CLI Select an option from the pg\_repack docs to [install the client CLI](https://reorg.github.io/pg_repack/#download). ### Syntax All pg\_repack commands should include the `-k` flag to skip the client-side superuser check. ```sh pg_repack -k [OPTION]... [DBNAME] ``` ## Example Perform an online `VACUUM FULL` on the tables `public.foo` and `public.bar` in the database `postgres`: ```sh pg_repack -k -h db..supabase.co -p 5432 -U postgres -d postgres --no-order --table public.foo --table public.bar ``` See the [official pg\_repack documentation](https://reorg.github.io/pg_repack/) for the full list of options. ## Limitations * pg\_repack cannot reorganize temporary tables. * pg\_repack cannot cluster tables by GiST indexes. * You cannot perform DDL commands of the target tables except VACUUM or ANALYZE while pg\_repack is working. pg\_repack holds an ACCESS SHARE lock on the target table to enforce this restriction. ## Resources * [Official pg\_repack documentation](https://reorg.github.io/pg_repack/) # pg_stat_statements: Query Performance Monitoring `pg_stat_statements` is a database extension that exposes a view, of the same name, to track statistics about SQL statements executed on the database. The following table shows some of the available statistics and metadata: | Column Name | Column Type | Description | | ----------------- | ------------------------------------ | ---------------------------------------------------------------------------------------------------------------------------- | | `userid` | `oid` (references `pg_authid.oid`) | OID of user who executed the statement | | `dbid` | `oid` (references `pg_database.oid`) | OID of database in which the statement was executed | | `toplevel` | `bool` | True if the query was executed as a top-level statement (always true if pg\_stat\_statements.track is set to top) | | `queryid` | `bigint` | Hash code to identify identical normalized queries. | | `query` | `text` | Text of a representative statement | | `plans` | `bigint` | Number of times the statement was planned (if pg\_stat\_statements.track\_planning is enabled, otherwise zero) | | `total_plan_time` | `double precision` | Total time spent planning the statement, in milliseconds (if pg\_stat\_statements.track\_planning is enabled, otherwise zero) | | `min_plan_time` | `double precision` | Minimum time spent planning the statement, in milliseconds (if pg\_stat\_statements.track\_planning is enabled, otherwise zero) | A full list of statistics is available in the [pg\_stat\_statements docs](https://www.postgresql.org/docs/current/pgstatstatements.html). For more information on query optimization, check out the [query performance guide](/docs/guides/platform/performance#examining-query-performance). ## Enable the extension ## Inspecting activity A common use for `pg_stat_statements` is to track down expensive or slow queries. The `pg_stat_statements` view contains a row for each executed query with statistics inlined. For example, you can leverage the statistics to identify frequently executed and slow queries against a given table. ```sql select calls, mean_exec_time, max_exec_time, total_exec_time, stddev_exec_time, query from pg_stat_statements where calls > 50 -- at least 50 calls and mean_exec_time > 2.0 -- averaging at least 2ms/call and total_exec_time > 60000 -- at least one minute total server time spent and query ilike '%user_in_organization%' -- filter to queries that touch the user_in_organization table order by calls desc ``` From the results, we can make an informed decision about which queries to optimize or index. ## Resources * Official [pg\_stat\_statements documentation](https://www.postgresql.org/docs/current/pgstatstatements.html) # PGAudit: Postgres Auditing [PGAudit](https://www.pgaudit.org) extends Postgres's built-in logging abilities. It can be used to selectively track activities within your database. This helps you with: * **Compliance**: Meeting audit requirements for regulations * **Security**: Detecting suspicious database activity * **Troubleshooting**: Identifying and fixing database issues ## Enable the extension ## Configure the extension PGAudit can be configured with different levels of precision. **PGAudit logging precision:** * **[Session](#session-logging):** Logs activity within a connection, such as a [psql](https://supabase.com/docs/guides/database/connecting-to-postgres#connecting-with-psql) connection. * **[User](#user-logging):** Logs activity by a particular database user (for example, `anon` or `postgres`). * **[Global](#global-logging):** Logs activity across the entire database. * **[Object](#object-logging):** Logs events related to specific database objects (for example, the auth.users table). Although Session, User, and Global modes differ in their precision, they're all considered variants of **Session Mode** and are configured with the same input categories. ### Session mode categories These modes can monitor predefined categories of database operations: | Category | What it Logs | Description | | ---------- | --------------------------------------------------------------------- | -------------------------------------------------------------------------- | | `read` | Data retrieval (SELECT, COPY) | Tracks what data is being accessed. | | `write` | Data modification (INSERT, DELETE, UPDATE, TRUNCATE, COPY) | Tracks changes made to your database. | | `function` | FUNCTION, PROCEDURE, and DO/END block executions | Tracks routine/function executions | | `role` | User management actions (CREATE, DROP, ALTER on users and privileges) | Tracks changes to user permissions and access. | | `ddl` | Schema changes (CREATE, DROP, ALTER statements) | Monitors modifications to your database structure (tables, indexes, etc.). | | `misc` | Less common commands (FETCH, CHECKPOINT) | Captures obscure actions for deeper analysis if needed. | | `all` | Everything above | Comprehensive logging for complete audit trails. | Below is a limited example of how to assign PGAudit to monitor specific categories. ```sql -- log all CREATE, ALTER, and DROP events ... pgaudit.log = 'ddl'; -- log all CREATE, ALTER, DROP, and SELECT events ... pgaudit.log = 'read, ddl'; -- log nothing ... pgaudit.log = 'none'; ``` ### Session logging When you are connecting in a session environment, such as a [psql](https://supabase.com/docs/guides/database/connecting-to-postgres#connecting-with-psql) connection, you can configure PGAudit to record events initiated within the session. Inside a session, by default, PGAudit will log nothing: ```sql -- returns 'none' show pgaudit.log; ``` In the session, you can `set` the `pgaudit.log` variable to record events: ```sql -- log CREATE, ALTER, and DROP events set pgaudit.log = 'ddl'; -- log all CREATE, ALTER, DROP, and SELECT events set pgaudit.log = 'read, ddl'; -- log nothing set pgaudit.log = 'none'; ``` ### User logging There are some cases where you may want to monitor a database user's actions. For instance, let's say you connected your database to [Zapier](https://supabase.com/partners/integrations/zapier) and created a custom role for it to use: ```sql create user "zapier" with password ''; ``` You may want to log all actions initiated by `zapier`, which can be done with the following command: ```sql alter role "zapier" set pgaudit.log to 'all'; ``` To remove the settings, execute the following code: ```sql -- disables role's log alter role "zapier" set pgaudit.log to 'none'; -- check to make sure the changes are finalized: select rolname, rolconfig from pg_roles where rolname = 'zapier'; -- should return a rolconfig path with "pgaudit.log=none" present ``` ### Global logging The below SQL configures PGAudit to record all events associated with the `postgres` role. Since it has extensive privileges, this effectively monitors all database activity. ```sql alter role "postgres" set pgaudit.log to 'all'; ``` To check if the `postgres` role is auditing, execute the following command: ```sql select rolname, rolconfig from pg_roles where rolname = 'postgres'; -- should return a rolconfig path with "pgaudit.log=all" present ``` To remove the settings, execute the following code: ```sql alter role "postgres" set pgaudit.log to 'none'; ``` ### Object logging To fine-tune what object events PGAudit will record, you must create a custom database role with limited permissions: ```sql create role "some_audit_role" noinherit; ``` No other Postgres user can assume or login via this role. It solely exists to securely define what PGAudit will record. Once the role is created, you can direct PGAudit to log by assigning it to the `pgaudit.role` variable: ```sql alter role "postgres" set pgaudit.role to 'some_audit_role'; ``` You can then assign the role to monitor only approved object events, such as `select` statements that include a specific table: ```sql grant select on random_table to "some_audit_role"; ``` With this privilege granted, PGAudit will record all select statements that reference the `random_table`, regardless of *who* or *what* actually initiated the event. All assignable privileges can be viewed in the [Postgres documentation](https://www.postgresql.org/docs/current/ddl-priv.html). If you would no longer like to use object logging, you will need to unassign the `pgaudit.role` variable: ```sql -- change pgaudit.role to no longer reference some_audit_role alter role "postgres" set pgaudit.role to ''; -- view if pgaudit.role changed with the following command: select rolname, rolconfig from pg_roles where rolname = 'postgres'; -- should return a rolconfig path with "pgaudit.role=" ``` ## Interpreting Audit Logs PGAudit was designed for storing logs as CSV files with the following headers: | header | Description | | --------------- | ----------------------------------------------------------------------------------------------------------------------------------------- | | AUDIT\_TYPE | SESSION or OBJECT | | STATEMENT\_ID | Unique statement ID for this session. Sequential even if some statements are not logged. | | SUBSTATEMENT\_ID | Sequential ID for each sub-statement within the main statement. Continuous even if some are not logged. | | CLASS | ..., READ, ROLE (see pgaudit.log). | | COMMAND | ..., ALTER TABLE, SELECT. | | OBJECT\_TYPE | TABLE, INDEX, VIEW, etc. Available for SELECT, DML, and most DDL statements. | | OBJECT\_NAME | The fully qualified object name (for example, public.account). Available for SELECT, DML, and most DDL. | | STATEMENT | Statement executed on the backend. | | PARAMETER | If pgaudit.log\_parameter is set, this field contains the statement parameters as quoted CSV, or \. Otherwise, it's \. | A log made from the following create statement: ```sql create table account ( id int primary key, name text, description text ); ``` Generates the following log in the [Dashboard's Postgres Logs](https://supabase.com/dashboard/project/_/logs/postgres-logs): AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.account,create table account( id int, name text, description text ); ## Finding and filtering audit logs Logs generated by PGAudit can be found in [Postgres Logs](https://supabase.com/dashboard/project/_/logs/postgres-logs?s=AUDIT). To find a specific log, you can use the log explorer. Below is a basic example to extract logs referencing `CREATE TABLE` events ```sql select cast(t.timestamp as datetime) as timestamp, event_message from postgres_logs as t cross join unnest(metadata) as m cross join unnest(m.parsed) as p where event_message like 'AUDIT%CREATE TABLE%' order by timestamp desc limit 100; ``` ## Practical examples ### Monitoring API events To monitor all writes initiated by the PostgREST API roles: ```sql alter role "authenticator" set pgaudit.log to 'write'; -- the above is the practical equivalent to: -- alter role "anon" set pgaudit.log TO 'write'; -- alter role "authenticated" set pgaudit.log TO 'write'; -- alter role "service_role" set pgaudit.log TO 'write'; ``` ### Monitoring the `auth.users` table In the worst case scenario, where a privileged roles' password is exposed, you can use PGAudit to monitor if the `auth.users` table was targeted. It should be stated that API requests are already monitored in the [API Edge Network](https://supabase.com/dashboard/project/_/logs/edge-logs) and this is more about providing greater clarity about what is happening at the database level. Logging `auth.user` should be done in Object Mode and requires a custom role: ```sql -- create logging role create role "auth_auditor" noinherit; -- give role permission to observe relevant table events grant select on auth.users to "auth_auditor"; grant delete on auth.users to "auth_auditor"; -- assign auth_auditor to pgaudit.role alter role "postgres" set pgaudit.role to 'auth_auditor'; ``` With the above code, any query involving reading or deleting from the auth.users table will be logged. ## Best practices ### Disabling excess logging PGAudit, if not configured mindfully, can log all database events, including background tasks. This can generate an undesirably large amount of logs in a few hours. The first step to solve this problem is to identify which database users PGAudit is observing: ```sql -- find all users monitored by pgaudit select rolname, rolconfig from pg_roles where exists ( select 1 from UNNEST(rolconfig) as c where c like '%pgaudit.role%' or c like '%pgaudit.log%' ); ``` To prevent PGAudit from monitoring the problematic roles, you'll want to change their `pgaudit.log` values to `none` and `pgaudit.role` values to `empty quotes ''` ```sql -- Use to disable object level logging alter role "" set pgaudit.role to ''; -- Use to disable global and user level logging alter role "" set pgaudit.log to 'none'; ``` ## FAQ #### Using PGAudit to debug database functions Technically yes, but it is not the best approach. It is better to check out our [function debugging guide](https://supabase.com/docs/guides/database/functions#general-logging) instead. #### Downloading database logs In the [Logs Dashboard](https://supabase.com/dashboard/project/_/logs/postgres-logs) you can download logs as CSVs. #### Logging observed table rows By default, PGAudit records queries, but not the returned rows. You can modify this behavior with the `pgaudit.log_rows` variable: ```sql --enable alter role "postgres" set pgaudit.log_rows to 'on'; -- disable alter role "postgres" set pgaudit.log_rows to 'off'; ``` You should not do this unless you are *absolutely* certain it is necessary for your use case. It can expose sensitive values to your logs that ideally should not be preserved. Furthermore, if done in excess, it can noticeably reduce database performance. #### Logging function parameters We don't currently support configuring `pgaudit.log_parameter` because it may log secrets in encrypted columns if you are using [pgsodium](https://supabase.com/docs/guides/database/extensions/pgsodium) or[Vault](https://supabase.com/docs/guides/database/vault). You can upvote this [feature request](https://github.com/orgs/supabase/discussions/20183) with your use-case if you'd like this restriction lifted. #### Does PGAudit support system wide configurations? PGAudit allows settings to be applied to 3 different database scopes: | Scope | Description | Configuration File/Command | | -------- | ------------------ | -------------------------- | | System | Entire server | ALTER SYSTEM commands | | Database | Specific database | ALTER DATABASE commands | | Role | Specific user/role | ALTER ROLE commands | Supabase limits full privileges for file system and database variables, meaning PGAudit modifications can only occur at the role level. Assigning PGAudit to the `postgres` role grants it nearly complete visibility into the database, making role-level adjustments a practical alternative to configuring at the database or system level. PGAudit's [official documentation](https://www.pgaudit.org) focuses on system and database level configs, but its docs officially supports role level configs, too. ## Resources * [Official `PGAudit` documentation](https://www.pgaudit.org) * [Database Function Logging](https://supabase.com/docs/guides/database/functions#general-logging) * [Supabase Logging](https://supabase.com/docs/guides/platform/logs) * [Self-Hosting Logs](https://supabase.com/docs/reference/self-hosting-analytics/introduction) # pgjwt: JSON Web Tokens The [`pgjwt`](https://github.com/michelp/pgjwt) (PostgreSQL JSON Web Token) extension allows you to create and parse [JSON Web Tokens (JWTs)](https://en.wikipedia.org/wiki/JSON_Web_Token) within a PostgreSQL database. JWTs are commonly used for authentication and authorization in web applications and services. ## Enable the extension ## API * [`sign(payload json, secret text, algorithm text default 'HSA256')`](https://github.com/michelp/pgjwt#usage): Signs a JWT containing *payload* with *secret* using *algorithm*. * [`verify(token text, secret text, algorithm text default 'HSA256')`](https://github.com/michelp/pgjwt#usage): Decodes a JWT *token* that was signed with *secret* using *algorithm*. Where: * `payload` is an encrypted JWT represented as a string. * `secret` is the private/secret passcode which is used to sign the JWT and verify its integrity. * `algorithm` is the method used to sign the JWT using the secret. * `token` is an encrypted JWT represented as a string. ## Usage Once the extension is installed, you can use its functions to create and parse JWTs. Here's an example of how you can use the `sign` function to create a JWT: ```sql select extensions.sign( payload := '{"sub":"1234567890","name":"John Doe","iat":1516239022}', secret := 'secret', algorithm := 'HS256' ); ``` The `pgjwt_encode` function returns a string that represents the JWT, which can then be safely transmitted between parties. sign --------------------------------- eyJhbGciOiJIUzI1NiIsInR5cCI6IkpX VCJ9.eyJzdWIiOiIxMjM0NTY3ODkwIiw ibmFtZSI6IkpvaG4gRG9lIiwiaWF0Ijo xNTE2MjM5MDIyfQ.XbPfbIHMI6arZ3Y9 22BhjWgQzWXcXNrz0ogtVhfEd2o (1 row) To parse a JWT and extract its claims, you can use the `verify` function. Here's an example: ```sql select extensions.verify( token := 'eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJuYW1lIjoiRm9vIn0.Q8hKjuadCEhnCPuqIj9bfLhTh_9QSxshTRsA5Aq4IuM', secret := 'secret', algorithm := 'HS256' ); ``` Which returns the decoded contents and some associated metadata. ```sql header | payload | valid -----------------------------+----------------+------- {"alg":"HS256","typ":"JWT"} | {"name":"Foo"} | t (1 row) ``` ## Resources * Official [`pgjwt` documentation](https://github.com/michelp/pgjwt) # pgmq: Queues See the [Supabase Queues docs](/docs/guides/queues). # PGroonga: Multilingual Full Text Search `PGroonga` is a Postgres extension adding a full text search indexing method based on [Groonga](https://groonga.org). While native Postgres supports full text indexing, it is limited to alphabet and digit based languages. `PGroonga` offers a wider range of character support making it viable for a superset of languages supported by Postgres including Japanese, Chinese, etc. ## Enable the extension ## Creating a full text search index Given a table with a `text` column: ```sql create table memos ( id serial primary key, content text ); ``` We can index the column for full text search with a `pgroonga` index: ```sql create index ix_memos_content ON memos USING pgroonga(content); ``` To test the full text index, we'll add some data. ```sql insert into memos(content) values ('PostgreSQL is a relational database management system.'), ('Groonga is a fast full text search engine that supports all languages.'), ('PGroonga is a PostgreSQL extension that uses Groonga as index.'), ('There is groonga command.'); ``` The Postgres query planner is smart enough to know that, for extremely small tables, it's faster to scan the whole table rather than loading an index. To force the index to be used, we can disable sequential scans: ```sql -- For testing only. Don't do this in production set enable_seqscan = off; ``` Now if we run an explain plan on a query filtering on `memos.content`: ```sql explain select * from memos where content like '%engine%'; QUERY PLAN ----------------------------------------------------------------------------- Index Scan using ix_memos_content on memos (cost=0.00..1.11 rows=1 width=36) Index Cond: (content ~~ '%engine%'::text) (2 rows) ``` The `pgroonga` index is used to retrieve the result set: ```markdown | id | content | | --- | ------------------------------------------------------------------------ | | 2 | 'Groonga is a fast full text search engine that supports all languages.' | ``` ## Full text search The `&@~` operator performs full text search. It returns any matching results. Unlike `LIKE` operator, `pgroonga` can search any text that contains the keyword case insensitive. Take the following example: ```sql select * from memos where content &@~ 'groonga'; ``` And the result: ```markdown id | content ----+------------------------------------------------------------------------ 2 | Groonga is a fast full text search engine that supports all languages. 3 | PGroonga is a PostgreSQL extension that uses Groonga as index. 4 | There is groonga command. (3 rows) ``` ### Match all search words To find all memos where content contains BOTH of the words `postgres` and `pgroonga`, we can just use space to separate each words: ```sql select * from memos where content &@~ 'postgres pgroonga'; ``` And the result: ```markdown id | content ----+---------------------------------------------------------------- 3 | PGroonga is a PostgreSQL extension that uses Groonga as index. (1 row) ``` ### Match any search words To find all memos where content contain ANY of the words `postgres` or `pgroonga`, use the upper case `OR`: ```sql select * from memos where content &@~ 'postgres OR pgroonga'; ``` And the result: ```markdown id | content ----+---------------------------------------------------------------- 1 | PostgreSQL is a relational database management system. 3 | PGroonga is a PostgreSQL extension that uses Groonga as index. (2 rows) ``` ### Search that matches words with negation To find all memos where content contain the word `postgres` but not `pgroonga`, use `-` symbol: ```sql select * from memos where content &@~ 'postgres -pgroonga'; ``` And the result: ```markdown id | content ----+-------------------------------------------------------- 1 | PostgreSQL is a relational database management system. (1 row) ``` ## Resources * Official [PGroonga documentation](https://pgroonga.github.io/tutorial/) # pgrouting: Geospatial Routing [`pgRouting`](http://pgrouting.org) is Postgres and [PostGIS](http://postgis.net) extension adding geospatial routing functionality. The core functionality of `pgRouting` is a set of path finding algorithms including: * All Pairs Shortest Path, Johnson’s Algorithm * All Pairs Shortest Path, Floyd-Warshall Algorithm * Shortest Path A\* * Bi-directional Dijkstra Shortest Path * Bi-directional A\* Shortest Path * Shortest Path Dijkstra * Driving Distance * K-Shortest Path, Multiple Alternative Paths * K-Dijkstra, One to Many Shortest Path * Traveling Sales Person * Turn Restriction Shortest Path (TRSP) ## Enable the extension ## Example As an example, we'll solve the [traveling salesperson problem](https://en.wikipedia.org/wiki/Travelling_salesman_problem) using the `pgRouting`'s `pgr_TSPeuclidean` function from some PostGIS coordinates. A summary of the traveling salesperson problem is, given a set of city coordinates, solve for a path that goes through each city and minimizes the total distance traveled. First we populate a table with some X, Y coordinates ```sql create table wi29 ( id bigint, x float, y float, geom geometry ); insert into wi29 (id, x, y) values (1,20833.3333,17100.0000), (2,20900.0000,17066.6667), (3,21300.0000,13016.6667), (4,21600.0000,14150.0000), (5,21600.0000,14966.6667), (6,21600.0000,16500.0000), (7,22183.3333,13133.3333), (8,22583.3333,14300.0000), (9,22683.3333,12716.6667), (10,23616.6667,15866.6667), (11,23700.0000,15933.3333), (12,23883.3333,14533.3333), (13,24166.6667,13250.0000), (14,25149.1667,12365.8333), (15,26133.3333,14500.0000), (16,26150.0000,10550.0000), (17,26283.3333,12766.6667), (18,26433.3333,13433.3333), (19,26550.0000,13850.0000), (20,26733.3333,11683.3333), (21,27026.1111,13051.9444), (22,27096.1111,13415.8333), (23,27153.6111,13203.3333), (24,27166.6667,9833.3333), (25,27233.3333,10450.0000), (26,27233.3333,11783.3333), (27,27266.6667,10383.3333), (28,27433.3333,12400.0000), (29,27462.5000,12992.2222); ``` Next we use the `pgr_TSPeuclidean` function to find the best path. ```sql select * from pgr_TSPeuclidean($$select * from wi29$$) ``` ```sql seq | node | cost | agg_cost -----+------+------------------+------------------ 1 | 1 | 0 | 0 2 | 2 | 74.535614157127 | 74.535614157127 3 | 6 | 900.617093380362 | 975.152707537489 4 | 10 | 2113.77757765045 | 3088.93028518793 5 | 11 | 106.718669615254 | 3195.64895480319 6 | 12 | 1411.95293791574 | 4607.60189271893 7 | 13 | 1314.23824873744 | 5921.84014145637 8 | 14 | 1321.76283931305 | 7243.60298076942 9 | 17 | 1202.91366735569 | 8446.5166481251 10 | 18 | 683.333268292684 | 9129.84991641779 11 | 15 | 1108.05137466134 | 10237.9012910791 12 | 19 | 772.082339448903 | 11009.983630528 13 | 22 | 697.666150054665 | 11707.6497805827 14 | 23 | 220.141999627513 | 11927.7917802102 15 | 21 | 197.926372783442 | 12125.7181529937 16 | 29 | 440.456596290771 | 12566.1747492844 17 | 28 | 592.939989005405 | 13159.1147382898 18 | 26 | 648.288376333318 | 13807.4031146231 19 | 20 | 509.901951359278 | 14317.3050659824 20 | 25 | 1330.83095428717 | 15648.1360202696 21 | 27 | 74.535658878487 | 15722.6716791481 22 | 24 | 559.016994374947 | 16281.688673523 23 | 16 | 1243.87392358622 | 17525.5625971092 24 | 9 | 4088.0585364911 | 21613.6211336004 25 | 7 | 650.85409697993 | 22264.4752305803 26 | 3 | 891.004385199336 | 23155.4796157796 27 | 4 | 1172.36699411442 | 24327.846609894 28 | 8 | 994.708187806297 | 25322.5547977003 29 | 5 | 1188.01888359478 | 26510.5736812951 30 | 1 | 2266.91173136004 | 28777.4854126552 ``` ## Resources * Official [`pgRouting` documentation](https://docs.pgrouting.org/latest/en/index.html) # pgsodium (pending deprecation): Encryption Features Supabase DOES NOT RECOMMEND any new usage of [`pgsodium`](https://github.com/michelp/pgsodium). The [`pgsodium`](https://github.com/michelp/pgsodium) extension is expected to go through a deprecation cycle in the near future. We will reach out to owners of impacted projects to assist with migrations away from [`pgsodium`](https://github.com/michelp/pgsodium) once the deprecation process begins. [`pgsodium`](https://github.com/michelp/pgsodium) is a Postgres extension which provides SQL access to [`libsodium`'s](https://doc.libsodium.org/) high-level cryptographic algorithms. Supabase previously documented two features derived from pgsodium. Namely [Server Key Management](https://github.com/michelp/pgsodium#server-key-management) and [Transparent Column Encryption](https://github.com/michelp/pgsodium#transparent-column-encryption). At this time, we do not recommend using either on the Supabase platform due to their high level of operational complexity and misconfiguration risk. Note that Supabase projects are encrypted at rest by default which likely is sufficient for your compliance needs e.g. SOC2 & HIPAA. ## Get the root encryption key for your Supabase project Encryption requires keys. Keeping the keys in the same database as the encrypted data would be unsafe. For more information about managing the `pgsodium` root encryption key on your Supabase project see **[encryption key location](/docs/guides/database/vault#encryption-key-location)**. This key is required to decrypt values stored in [Supabase Vault](/docs/guides/database/vault) and data encrypted with Transparent Column Encryption. ## Resources * [Supabase Vault](/docs/guides/database/vault) * Read more about Supabase Vault in the [blog post](https://supabase.com/blog/vault-now-in-beta) * [Supabase Vault on GitHub](https://github.com/supabase/vault) ## Resources * Official [`pgsodium` documentation](https://github.com/michelp/pgsodium) # pgTAP: Unit Testing `pgTAP` is a unit testing extension for Postgres. ## Overview Let's cover some basic concepts: * Unit tests: allow you to test small parts of a system (like a database table!). * TAP: stands for [Test Anything Protocol](http://testanything.org/). It is an framework which aims to simplify the error reporting during testing. ## Enable the extension ## Testing tables ```sql begin; select plan( 1 ); select has_table( 'profiles' ); select * from finish(); rollback; ``` API: * [`has_table()`](https://pgtap.org/documentation.html#has_table): Tests whether or not a table exists in the database * [`has_index()`](https://pgtap.org/documentation.html#has_index): Checks for the existence of a named index associated with the named table. * [`has_relation()`](https://pgtap.org/documentation.html#has_relation): Tests whether or not a relation exists in the database. ## Testing columns ```sql begin; select plan( 2 ); select has_column( 'profiles', 'id' ); -- test that the "id" column exists in the "profiles" table select col_is_pk( 'profiles', 'id' ); -- test that the "id" column is a primary key select * from finish(); rollback; ``` API: * [`has_column()`](https://pgtap.org/documentation.html#has_column): Tests whether or not a column exists in a given table, view, materialized view or composite type. * [`col_is_pk()`](https://pgtap.org/documentation.html#col_is_pk): Tests whether the specified column or columns in a table is/are the primary key for that table. ## Testing RLS policies ```sql begin; select plan( 1 ); select policies_are( 'public', 'profiles', ARRAY [ 'Profiles are public', -- Test that there is a policy called "Profiles are public" on the "profiles" table. 'Profiles can only be updated by the owner' -- Test that there is a policy called "Profiles can only be updated by the owner" on the "profiles" table. ] ); select * from finish(); rollback; ``` API: * [`policies_are()`](https://pgtap.org/documentation.html#policies_are): Tests that all of the policies on the named table are only the policies that should be on that table. * [`policy_roles_are()`](https://pgtap.org/documentation.html#policy_roles_are): Tests whether the roles to which policy applies are only the roles that should be on that policy. * [`policy_cmd_is()`](https://pgtap.org/documentation.html#policy_cmd_is): Tests whether the command to which policy applies is same as command that is given in function arguments. You can also use the `results_eq()` method to test that a Policy returns the correct data: ```sql begin; select plan( 1 ); select results_eq( 'select * from profiles()', $$VALUES ( 1, 'Anna'), (2, 'Bruce'), (3, 'Caryn')$$, 'profiles() should return all users' ); select * from finish(); rollback; ``` API: * [`results_eq()`](https://pgtap.org/documentation.html#results_eq) * [`results_ne()`](https://pgtap.org/documentation.html#results_ne) ## Testing functions ```sql prepare hello_expr as select 'hello' begin; select plan(3); -- You'll need to create a hello_world and is_even function select function_returns( 'hello_world', 'text' ); -- test if the function "hello_world" returns text select function_returns( 'is_even', ARRAY['integer'], 'boolean' ); -- test if the function "is_even" returns a boolean select results_eq('select * from hello_world()', 'hello_expr'); -- test if the function "hello_world" returns "hello" select * from finish(); rollback; ``` API: * [`function_returns()`](https://pgtap.org/documentation.html#function_returns): Tests that a particular function returns a particular data type * [`is_definer()`](https://pgtap.org/documentation.html#is_definer): Tests that a function is a security definer (that is, a `setuid` function). ## Resources * Official [`pgTAP` documentation](https://pgtap.org/) # pgvector: Embeddings and vector similarity [pgvector](https://github.com/pgvector/pgvector/) is a Postgres extension for vector similarity search. It can also be used for storing [embeddings](https://supabase.com/blog/openai-embeddings-postgres-vector). Learn more about Supabase's [AI & Vector](/docs/guides/ai) offering. ## Concepts ### Vector similarity Vector similarity refers to a measure of the similarity between two related items. For example, if you have a list of products, you can use vector similarity to find similar products. To do this, you need to convert each product into a "vector" of numbers, using a mathematical model. You can use a similar model for text, images, and other types of data. Once all of these vectors are stored in the database, you can use vector similarity to find similar items. ### Embeddings This is particularly useful if you're building on top of OpenAI's [GPT-3](https://openai.com/blog/gpt-3-apps/). You can create and store [embeddings](/docs/guides/ai/quickstarts/generate-text-embeddings) for retrieval augmented generation. ## Usage ### Enable the extension ## Usage ### Create a table to store vectors ```sql create table posts ( id serial primary key, title text not null, body text not null, embedding vector(384) ); ``` ### Storing a vector / embedding In this example we'll generate a vector using Transformer.js, then store it in the database using the Supabase client. ```js import { pipeline } from '@xenova/transformers' const generateEmbedding = await pipeline('feature-extraction', 'Supabase/gte-small') const title = 'First post!' const body = 'Hello world!' // Generate a vector using Transformers.js const output = await generateEmbedding(body, { pooling: 'mean', normalize: true, }) // Extract the embedding output const embedding = Array.from(output.data) // Store the vector in Postgres const { data, error } = await supabase.from('posts').insert({ title, body, embedding, }) ``` ## Specific usage cases ### Queries with filtering If you use an IVFFlat or HNSW index and naively filter the results based on the value of another column, you may get fewer rows returned than requested. For example, the following query may return fewer than 5 rows, even if 5 corresponding rows exist in the database. This is because the embedding index may not return 5 rows matching the filter. SELECT * FROM items WHERE category_id = 123 ORDER BY embedding <-> '[3,1,2]' LIMIT 5; To get the exact number of requested rows, use [iterative search](https://github.com/pgvector/pgvector/?tab=readme-ov-file#iterative-index-scans) to continue scanning the index until enough results are found. ## More pgvector and Supabase resources * [Supabase Clippy: ChatGPT for Supabase Docs](https://supabase.com/blog/chatgpt-supabase-docs) * [Storing OpenAI embeddings in Postgres with pgvector](https://supabase.com/blog/openai-embeddings-postgres-vector) * [A ChatGPT Plugins Template built with Supabase Edge Runtime](https://supabase.com/blog/building-chatgpt-plugins-template) * [Template for building your own custom ChatGPT style doc search](https://github.com/supabase-community/nextjs-openai-doc-search) # plpgsql_check: PL/pgSQL Linter [plpgsql\_check](https://github.com/okbob/plpgsql_check) is a Postgres extension that lints plpgsql for syntax, semantic and other related issues. The tool helps developers to identify and correct errors before executing the code. plpgsql\_check is most useful for developers who are working with large or complex SQL codebases, as it can help identify and resolve issues early in the development cycle. ## Enable the extension ## API * [`plpgsql_check_function( ... )`](https://github.com/okbob/plpgsql_check#active-mode): Scans a function for errors. `plpgsql_check_function` is highly customizable. For a complete list of available arguments see [the docs](https://github.com/okbob/plpgsql_check#arguments) ## Usage To demonstrate `plpgsql_check` we can create a function with a known error. In this case we create a function `some_func`, that references a non-existent column `place.created_at`. ```sql create table place( x float, y float ); create or replace function public.some_func() returns void language plpgsql as $$ declare rec record; begin for rec in select * from place loop -- Bug: There is no column `created_at` on table `place` raise notice '%', rec.created_at; end loop; end; $$; ``` Note that executing the function would not catch the invalid reference error because the `loop` does not execute if no rows are present in the table. ```sql select public.some_func(); some_func ─────────── (1 row) ``` Now we can use plpgsql\_check's `plpgsql_check_function` function to identify the known error. ```sql select plpgsql_check_function('public.some_func()'); plpgsql_check_function ------------------------------------------------------------ error:42703:8:RAISE:record "rec" has no field "created_at" Context: SQL expression "rec.created_at" ``` ## Resources * Official [`plpgsql_check` documentation](https://github.com/okbob/plpgsql_check) # plv8: JavaScript Language The `plv8` extension allows you use JavaScript within Postgres. ## Overview While Postgres natively runs SQL, it can also run other procedural languages. `plv8` allows you to run JavaScript code - specifically any code that runs on the [V8 JavaScript engine](https://v8.dev). It can be used for database functions, triggers, queries and more. ## Enable the extension ## Create `plv8` functions Functions written in `plv8` are written just like any other Postgres functions, only with the `language` identifier set to `plv8`. ```sql create or replace function function_name() returns void as $$ // V8 JavaScript // code // here $$ language plv8; ``` You can call `plv8` functions like any other Postgres function: ## Examples ### Scalar functions A [scalar function](https://plv8.github.io/#scalar-function-calls) is anything that takes in some user input and returns a single result. ```sql create or replace function hello_world(name text) returns text as $$ let output = `Hello, ${name}!`; return output; $$ language plv8; ``` ### Executing SQL You can execute SQL within `plv8` code using the [`plv8.execute` function](https://plv8.github.io/#plv8-execute). ```sql create or replace function update_user(id bigint, first_name text) returns smallint as $$ var num_affected = plv8.execute( 'update profiles set first_name = $1 where id = $2', [first_name, id] ); return num_affected; $$ language plv8; ``` ### Set-returning functions A [set-returning function](https://plv8.github.io/#set-returning-function-calls) is anything that returns a full set of results - for example, rows in a table. ```sql create or replace function get_messages() returns setof messages as $$ var json_result = plv8.execute( 'select * from messages' ); return json_result; $$ language plv8; select * from get_messages(); ``` ## Resources * Official [`plv8` documentation](https://plv8.github.io/) * [plv8 GitHub Repository](https://github.com/plv8/plv8) # PostGIS: Geo queries [PostGIS](https://postgis.net/) is a Postgres extension that allows you to interact with Geo data within Postgres. You can sort your data by geographic location, get data within certain geographic boundaries, and do much more with it. ## Overview While you may be able to store simple lat/long geographic coordinates as a set of decimals, it does not scale very well when you try to query through a large data set. PostGIS comes with special data types that are efficient, and indexable for high scalability. The additional data types that PostGIS provides include [Point](https://postgis.net/docs/using_postgis_dbmanagement.html#Point), [Polygon](https://postgis.net/docs/using_postgis_dbmanagement.html#Polygon), [LineString](https://postgis.net/docs/using_postgis_dbmanagement.html#LineString), and many more to represent different types of geographical data. In this guide, we will mainly focus on how to interact with `Point` type, which represents a single set of latitude and longitude. If you are interested in digging deeper, you can learn more about different data types on the [data management section of PostGIS docs](https://postgis.net/docs/using_postgis_dbmanagement.html). ## Enable the extension You can get started with PostGIS by enabling the PostGIS extension in your Supabase dashboard. ## Examples Now that we are ready to get started with PostGIS, let’s create a table and see how we can utilize PostGIS for some typical use cases. Let’s imagine we are creating a simple restaurant-searching app. Let’s create our table. Each row represents a restaurant with its location stored in `location` column as a `Point` type. ```sql create table if not exists public.restaurants ( id int generated by default as identity primary key, name text not null, location gis.geography(POINT) not null ); ``` We can then set a [spatial index](https://postgis.net/docs/using_postgis_dbmanagement.html#build-indexes) on the `location` column of this table. ```sql create index restaurants_geo_index on public.restaurants using GIST (location); ``` ### Inserting data You can insert geographical data through SQL or through our API. Notice the order in which you pass the latitude and longitude. Longitude comes first, and is because longitude represents the x-axis of the location. Another thing to watch for is when inserting data from the client library, there is no comma between the two values, just a single space. At this point, if you go into your Supabase dashboard and look at the data, you will notice that the value of the `location` column looks something like this. 0101000020E6100000A4DFBE0E9C91614044FAEDEBC0494240 We can query the `restaurants` table directly, but it will return the `location` column in the format you see above. We will create [database functions](https://supabase.com/docs/guides/database/functions) so that we can use the [st\_y()](https://postgis.net/docs/ST_Y.html) and [st\_x()](https://postgis.net/docs/ST_X.html) function to convert it back to lat and long floating values. ### Order by distance Sorting datasets from closest to farthest, sometimes called nearest-neighbor sort, is a very common use case in Geo-queries. PostGIS can handle it with the use of the [`<->`](https://postgis.net/docs/geometry_distance_knn.html) operator. `<->` operator returns the two-dimensional distance between two geometries and will utilize the spatial index when used within `order by` clause. You can create the following database function to sort the restaurants from closest to farthest by passing the current locations as parameters. ```sql create or replace function nearby_restaurants(lat float, long float) returns table (id public.restaurants.id%TYPE, name public.restaurants.name%TYPE, lat float, long float, dist_meters float) set search_path = '' language sql as $$ select id, name, gis.st_y(location::gis.geometry) as lat, gis.st_x(location::gis.geometry) as long, gis.st_distance(location, gis.st_point(long, lat)::gis.geography) as dist_meters from public.restaurants order by location operator(gis.<->) gis.st_point(long, lat)::gis.geography; $$; ``` Before being able to call this function from our client we need to grant access to our `gis` schema: ```sql grant usage on schema gis to anon, authenticated; ``` Now you can call this function from your client using `rpc()` like this: ### Finding all data points within a bounding box ![Searching within a bounding box of a map](/docs/img/guides/database/extensions/postgis/map.png) When you are working on a map-based application where the user scrolls through your map, you might want to load the data that lies within the bounding box of the map every time your users scroll. PostGIS can return the rows that are within the bounding box just by supplying the bottom left and the top right coordinates. Let’s look at what the function would look like: ```sql create or replace function restaurants_in_view(min_lat float, min_long float, max_lat float, max_long float) returns table (id public.restaurants.id%TYPE, name public.restaurants.name%TYPE, lat float, long float) set search_path to '' language sql as $$ select id, name, gis.st_y(location::gis.geometry) as lat, gis.st_x(location::gis.geometry) as long from public.restaurants where location operator(gis.&&) gis.ST_SetSRID(gis.ST_MakeBox2D(gis.ST_Point(min_long, min_lat), gis.ST_Point(max_long, max_lat)), 4326) $$; ``` The [`&&`](https://postgis.net/docs/geometry_overlaps.html) operator used in the `where` statement here returns a boolean of whether the bounding box of the two geometries intersect or not. We are basically creating a bounding box from the two points and finding those points that fall under the bounding box. We are also utilizing a few different PostGIS functions: * [ST\_MakeBox2D](https://postgis.net/docs/ST_MakeBox2D.html): Creates a 2-dimensional box from two points. * [ST\_SetSRID](https://postgis.net/docs/ST_SetSRID.html): Sets the [SRID](https://postgis.net/docs/manual-dev/using_postgis_dbmanagement.html#spatial_ref_sys), which is an identifier of what coordinate system to use for the geometry. 4326 is the standard longitude and latitude coordinate system. You can call this function from your client using `rpc()` like this: ## Troubleshooting As of PostGIS 2.3 or newer, the PostGIS extension is no longer relocatable from one schema to another. If you need to move it from one schema to another for any reason (e.g. from the public schema to the extensions schema for security reasons), you would normally run a ALTER EXTENSION to relocate the schema. However, you will now to do the following steps: 1. Backup your Database to prevent data loss - You can do this through the [CLI](https://supabase.com/docs/reference/cli/supabase-db-dump) or Postgres backup tools such as [pg\_dumpall](https://www.postgresql.org/docs/current/backup-dump.html#BACKUP-DUMP-ALL) 2. Drop all dependencies you created and the PostGIS extension - `DROP EXTENSION postgis CASCADE;` 3. Enable PostGIS extension in the new schema - `CREATE EXTENSION postgis SCHEMA extensions;` 4. Restore dropped data via the Backup if necessary from step 1 with your tool of choice. ## Resources * [Official PostGIS documentation](https://postgis.net/documentation/) # postgres_fdw The extension enables Postgres to query tables and views on a remote Postgres server. ## Enable the extension ## Create a connection to another database ### Configuring execution options #### Fetch\_size Maximum rows fetched per operation. For example, fetching 200 rows with `fetch_size` set to 100 requires 2 requests. ```sql alter server "" options (fetch_size '10000'); ``` #### Batch\_size Maximum rows inserted per cycle. For example, inserting 200 rows with `batch_size` set to 100 requires 2 requests. ```sql alter server "" options (batch_size '1000'); ``` #### Extensions Lists shared extensions. Without them, queries involving unlisted extension functions or operators may fail or omit references. ```sql alter server "" options (extensions 'vector, postgis'); ``` For more server options, check the extension's [official documentation](https://www.postgresql.org/docs/current/postgres-fdw.html#POSTGRES-FDW) ## Resources * Official [`postgres_fdw` documentation](https://www.postgresql.org/docs/current/postgres-fdw.html#POSTGRES-FDW) # RUM: improved inverted index for full-text search based on GIN index [RUM](https://github.com/postgrespro/rum) is an extension which adds a RUM index to Postgres. RUM index is based on GIN that stores additional per-entry information in a posting tree. For example, positional information of lexemes or timestamps. In comparison to GIN it can use this information to make faster index-only scans for: * Phrase search * Text search with ranking by text distance operator * Text `SELECT`s with ordering by some non-indexed additional column e.g. by timestamp. RUM works best in scenarios when the possible keys are highly repeatable. I.e. all texts are composed of a limited amount of words, so per-lexeme indexing gives significant speed-up in searching texts containing word combinations or phrases. Main operators for ordering are: `tsvector` `<=>` `tsquery` | `float4` | Distance between `tsvector` and `tsquery`. value `<=>` value | `float8` | Distance between two values. Where value is `timestamp`, `timestamptz`, `int2`, `int4`, `int8`, `float4`, `float8`, `money` and `oid` ## Usage ### Enable the extension You can get started with rum by enabling the extension in your Supabase dashboard. ### Syntax #### For type: `tsvector` To understand the following you may need first to see [Official Postgres documentation on text search](https://www.postgresql.org/docs/current/functions-textsearch.html) `rum_tsvector_ops` ```sql CREATE TABLE test_rum(t text, a tsvector); CREATE TRIGGER tsvectorupdate BEFORE UPDATE OR INSERT ON test_rum FOR EACH ROW EXECUTE PROCEDURE tsvector_update_trigger('a', 'pg_catalog.english', 't'); INSERT INTO test_rum(t) VALUES ('The situation is most beautiful'); INSERT INTO test_rum(t) VALUES ('It is a beautiful'); INSERT INTO test_rum(t) VALUES ('It looks like a beautiful place'); CREATE INDEX rumidx ON test_rum USING rum (a rum_tsvector_ops); ``` And we can execute `tsvector` selects with ordering by text distance operator: ```sql SELECT t, a `<=>` to_tsquery('english', 'beautiful | place') AS rank FROM test_rum WHERE a @@ to_tsquery('english', 'beautiful | place') ORDER BY a `<=>` to_tsquery('english', 'beautiful | place'); t | rank ---------------------------------+--------- It looks like a beautiful place | 8.22467 The situation is most beautiful | 16.4493 It is a beautiful | 16.4493 (3 rows) ``` `rum_tsvector_addon_ops` ```sql CREATE TABLE tsts (id int, t tsvector, d timestamp); CREATE INDEX tsts_idx ON tsts USING rum (t rum_tsvector_addon_ops, d) WITH (attach = 'd', to = 't'); ``` Now we can execute the selects with ordering distance operator on attached column: ```sql SELECT id, d, d `<=>` '2016-05-16 14:21:25' FROM tsts WHERE t @@ 'wr&qh' ORDER BY d `<=>` '2016-05-16 14:21:25' LIMIT 5; id | d | ?column? -----+---------------------------------+--------------- 355 | Mon May 16 14:21:22.326724 2016 | 2.673276 354 | Mon May 16 13:21:22.326724 2016 | 3602.673276 371 | Tue May 17 06:21:22.326724 2016 | 57597.326724 406 | Wed May 18 17:21:22.326724 2016 | 183597.326724 415 | Thu May 19 02:21:22.326724 2016 | 215997.326724 (5 rows) ``` #### For type: `anyarray` `rum_anyarray_ops` This operator class stores `anyarray` elements with length of the array. It supports operators `&&`, `@>`, `<@`, `=`, `%` operators. It also supports ordering by `<=>` operator. ```sql CREATE TABLE test_array (i int2[]); INSERT INTO test_array VALUES ('{}'), ('{0}'), ('{1,2,3,4}'), ('{1,2,3}'), ('{1,2}'), ('{1}'); CREATE INDEX idx_array ON test_array USING rum (i rum_anyarray_ops); ``` Now we can execute the query using index scan: ```sql SELECT * FROM test_array WHERE i && '{1}' ORDER BY i `<=>` '{1}' ASC; i ----------- {1} {1,2} {1,2,3} {1,2,3,4} (4 rows) ``` `rum_anyarray_addon_ops` The does the same with `anyarray` index as `rum_tsvector_addon_ops` i.e. allows to order select results using distance operator by attached column. ## Limitations `RUM` has slower build and insert times than `GIN` due to: 1. It is bigger due to the additional attributes stored in the index. 2. It uses generic WAL records. ## Resources * [Official RUM documentation](https://github.com/postgrespro/rum) # timescaledb: Time-Series data [`timescaledb`](https://docs.timescale.com/timescaledb/latest/) is a Postgres extension designed for improved handling of time-series data. It provides a scalable, high-performance solution for storing and querying time-series data on top of a standard Postgres database. `timescaledb` uses a time-series-aware storage model and indexing techniques to improve performance of Postgres in working with time-series data. The extension divides data into chunks based on time intervals, allowing it to scale efficiently, especially for large data sets. The data is then compressed, optimized for write-heavy workloads, and partitioned for parallel processing. `timescaledb` also includes a set of functions, operators, and indexes that work with time-series data to reduce query times, and make data easier to work with. ## Enable the extension ## Usage To demonstrate how `timescaledb` works, let's consider a simple example where we have a table that stores temperature data from different sensors. We will create a table named "temperatures" and store data for two sensors. First we create a hypertable, which is a virtual table that is partitioned into chunks based on time intervals. The hypertable acts as a proxy for the actual table and makes it easy to query and manage time-series data. ```sql create table temperatures ( time timestamptz not null, sensor_id int not null, temperature double precision not null ); select create_hypertable('temperatures', 'time'); ``` Next, we can populate some values ```sql insert into temperatures (time, sensor_id, temperature) values ('2023-02-14 09:00:00', 1, 23.5), ('2023-02-14 09:00:00', 2, 21.2), ('2023-02-14 09:05:00', 1, 24.5), ('2023-02-14 09:05:00', 2, 22.3), ('2023-02-14 09:10:00', 1, 25.1), ('2023-02-14 09:10:00', 2, 23.9), ('2023-02-14 09:15:00', 1, 24.9), ('2023-02-14 09:15:00', 2, 22.7), ('2023-02-14 09:20:00', 1, 24.7), ('2023-02-14 09:20:00', 2, 23.5); ``` And finally we can query the table using `timescaledb`'s `time_bucket` function to divide the time-series into intervals of the specified size (in this case, 1 hour) averaging the `temperature` reading within each group. ```sql select time_bucket('1 hour', time) AS hour, avg(temperature) AS average_temperature from temperatures where sensor_id = 1 and time > NOW() - interval '1 hour' group by hour; ``` ## Resources * Official [`timescaledb` documentation](https://docs.timescale.com/timescaledb/latest/) # uuid-ossp: Unique Identifiers The `uuid-ossp` extension can be used to generate a `UUID`. ## Overview A `UUID` is a "Universally Unique Identifier" and it is, for practical purposes, unique. This makes them particularly well suited as Primary Keys. It is occasionally referred to as a `GUID`, which stands for "Globally Unique Identifier". ## Enable the extension **Note**: Currently `uuid-ossp` extension is enabled by default and cannot be disabled. ## The `uuid` type Once the extension is enabled, you now have access to a `uuid` type. ## `uuid_generate_v1()` Creates a UUID value based on the combination of computer’s MAC address, current timestamp, and a random value. ## `uuid_generate_v4()` Creates UUID values based solely on random numbers. You can also use Postgres's built-in [`gen_random_uuid()`](https://www.postgresql.org/docs/current/functions-uuid.html) function to generate a UUIDv4. ## Examples ### Within a query ```sql select uuid_generate_v4(); ``` ### As a primary key Automatically create a unique, random ID in a table: ```sql create table contacts ( id uuid default uuid_generate_v4(), first_name text, last_name text, primary key (id) ); ``` ## Resources * [Choosing a Postgres Primary Key](https://supabase.com/blog/choosing-a-postgres-primary-key) * [The Basics Of Postgres `UUID` Data Type](https://www.postgresqltutorial.com/postgresql-uuid/) # Foreign Data Wrappers Connecting to external systems using Postgres Foreign Data Wrappers. Foreign Data Wrappers (FDW) are a core feature of Postgres that allow you to access and query data stored in external data sources as if they were native Postgres tables. Postgres includes several built-in foreign data wrappers, such as [`postgres_fdw`](https://www.postgresql.org/docs/current/postgres-fdw.html) for accessing other Postgres databases, and [`file_fdw`](https://www.postgresql.org/docs/current/file-fdw.html) for reading data from files. Supabase extends this feature to query other databases or any other external systems. We do this with our open source [Wrappers](https://github.com/supabase/wrappers) framework. In these guides we'll refer to them as "Wrappers", Foreign Data Wrappers, or FDWs. They are conceptually the same thing. ## Concepts Wrappers introduce some new terminology and different workflows. ### Remote servers A Remote Server is an external database, API, or any system containing data that you want to query from your Postgres database. Examples include: * An external database, like Postgres or Firebase. * A remote data warehouse, like ClickHouse, BigQuery, or Snowflake. * An API, like Stripe or GitHub. It's possible to connect to multiple remote servers of the same type. For example, you can connect to two different Firebase projects within the same Supabase database. ### Foreign tables A table in your database which maps to some data inside a Remote Server. Examples: * An `analytics` table which maps to a table inside your data warehouse. * A `subscriptions` table which maps to your Stripe subscriptions. * A `collections` table which maps to a Firebase collection. Although a foreign table behaves like any other table, the data is not stored inside your database. The data remains inside the Remote Server. ### ETL with Wrappers ETL stands for Extract, Transform, Load. It's an established process for moving data from one system to another. For example, it's common to move data from a production database to a data warehouse. There are many popular ETL tools, such as [Fivetran](https://fivetran.com/) and [Airbyte](https://airbyte.io/). Wrappers provide an alternative to these tools. You can use SQL to move data from one table to another: ```sql -- Copy data from your production database to your -- data warehouse for the last 24 hours: insert into warehouse.analytics select * from public.analytics where ts > (now() - interval '1 DAY'); ``` This approach provides several benefits: 1. **Simplicity:** the Wrappers API is just SQL, so data engineers don't need to learn new tools and languages. 2. **Save on time:** avoid setting up additional data pipelines. 3. **Save on Data Engineering costs:** less infrastructure to be managed. One disadvantage is that Wrappers are not as feature-rich as ETL tools. They also couple the ETL process to your database. ### On-demand ETL with Wrappers Supabase extends the ETL concept with real-time data access. Instead of moving gigabytes of data from one system to another before you can query it, you can instead query the data directly from the remote server. This additional option, "Query", extends the ETL process and is called [QETL](https://www.sciencedirect.com/science/article/abs/pii/S0169023X1730438X) (pronounced "kettle"): Query, Extract, Transform, Load. ```sql -- Get all purchases for a user from your data warehouse: select auth.users.id as user_id, warehouse.orders.id as order_id from warehouse.orders join auth.users on auth.users.id = warehouse.orders.user_id where auth.users.id = ''; ``` This approach has several benefits: 1. **On-demand:** analytical data is immediately available within your application with no additional infrastructure. 2. **Always in sync:** since the data is queried directly from the remote server, it's always up-to-date. 3. **Integrated:** large datasets are available within your application, and can be joined with your operational/transactional data. 4. **Save on bandwidth:** only extract/load what you need. ### Batch ETL with Wrappers A common use case for Wrappers is to extract data from a production database and load it into a data warehouse. This can be done within your database using [pg\_cron](/docs/guides/database/extensions/pg_cron). For example, you can schedule a job to run every night to extract data from your production database and load it into your data warehouse. ```sql -- Every day at 3am, copy data from your -- production database to your data warehouse: select cron.schedule( 'nightly-etl', '0 3 * * *', $$ insert into warehouse.analytics select * from public.analytics where ts > (now() - interval '1 DAY'); $$ ); ``` This process can be taxing on your database if you are moving large amounts of data. Often, it's better to use an external tool for batch ETL, such as [Fivetran](https://fivetran.com/) or [Airbyte](https://airbyte.io/). ### WebAssembly Wrappers WebAssembly (Wasm) is a binary instruction format that enables high-performance execution of code on the web. Wrappers now includes a Wasm runtime, which provides a sandboxed execution environment, to run Wasm foreign data wrappers. Combined Wrappers with Wasm, developing and distributing new FDW becomes much easier and you can even build your own Wasm FDW and use it on Supabase platform. To learn more about Wasm FDW, visit [Wrappers official documentation](https://supabase.github.io/wrappers/). ## Security Foreign Data Wrappers do not provide Row Level Security, thus it is not advised to expose them via your API. Wrappers should *always* be stored in a private schema. For example, if you are connecting to your Stripe account, you should create a `stripe` schema to store all of your foreign tables inside. This schema should *not* be added to the “Additional Schemas” setting in the API section. If you want to expose any of the foreign table columns to your public API, you can create a [Database Function with security definer](https://supabase.com/docs/guides/database/functions#security-definer-vs-invoker) in the `public` schema, and then you can interact with your foreign table through API. For better access control, the function should have appropriate filters on the foreign table to apply security rules based on your business needs. As an example, go to [SQL Editor](https://supabase.com/dashboard/project/_/sql/new) and then follow below steps, 1. Create a Stripe Products foreign table: ```sql create foreign table stripe.stripe_products ( id text, name text, active bool, default_price text, description text, created timestamp, updated timestamp, attrs jsonb ) server stripe_fdw_server options ( object 'products', rowid_column 'id' ); ``` 2. Create a security definer function that queries the foreign table and filters on the name prefix parameter: ```sql create function public.get_stripe_products(name_prefix text) returns table ( id text, name text, active boolean, default_price text, description text ) language plpgsql security definer set search_path = '' as $$ begin return query select t.id, t.name, t.active, t.default_price, t.description from stripe.stripe_products t where t.name like name_prefix || '%' ; end; $$; ``` 3. Restrict the function execution to a specific role only, for example, the authenticated users: ```sql -- revoke public execute permission revoke execute on function public.get_stripe_products from public; revoke execute on function public.get_stripe_products from anon; -- grant execute permission to a specific role only grant execute on function public.get_stripe_products to authenticated; ``` Once the preceding steps are finished, the function can be invoked from Supabase client to query the foreign table: ```js const { data, error } = await supabase .rpc('get_stripe_products', { name_prefix: 'Test' }) .select('*') if (error) console.error(error) else console.log(data) ``` ## Resources * Official [`supabase/wrappers` documentation](https://supabase.github.io/wrappers/) # Full Text Search How to use full text search in PostgreSQL. Postgres has built-in functions to handle `Full Text Search` queries. This is like a "search engine" within Postgres. ## Preparation For this guide we'll use the following example data: ## Usage The functions we'll cover in this guide are: ### `to_tsvector()` \[#to-tsvector] Converts your data into searchable tokens. `to_tsvector()` stands for "to text search vector." For example: ```sql select to_tsvector('green eggs and ham'); -- Returns 'egg':2 'green':1 'ham':4 ``` Collectively these tokens are called a "document" which Postgres can use for comparisons. ### `to_tsquery()` \[#to-tsquery] Converts a query string into tokens to match. `to_tsquery()` stands for "to text search query." This conversion step is important because we will want to "fuzzy match" on keywords. For example if a user searches for `eggs`, and a column has the value `egg`, we probably still want to return a match. ### Match: `@@` \[#match] The `@@` symbol is the "match" symbol for Full Text Search. It returns any matches between a `to_tsvector` result and a `to_tsquery` result. Take the following example: The equality symbol above (`=`) is very "strict" on what it matches. In a full text search context, we might want to find all "Harry Potter" books and so we can rewrite the example above: ## Basic full text queries ### Search a single column To find all `books` where the `description` contain the word `big`: ### Search multiple columns Right now there is no direct way to use JavaScript or Dart to search through multiple columns but you can do it by creating [computed columns](https://postgrest.org/en/stable/api.html#computed-virtual-columns) on the database. To find all `books` where `description` or `title` contain the word `little`: ### Match all search words To find all `books` where `description` contains BOTH of the words `little` and `big`, we can use the `&` symbol: ### Match any search words To find all `books` where `description` contain ANY of the words `little` or `big`, use the `|` symbol: Notice how searching for `big` includes results with the word `bigger` (or `biggest`, etc). ## Partial search Partial search is particularly useful when you want to find matches on substrings within your data. ### Implementing partial search You can use the `:*` syntax with `to_tsquery()`. Here's an example that searches for any book titles beginning with "Lit": ```sql select title from books where to_tsvector(title) @@ to_tsquery('Lit:*'); ``` ### Extending functionality with RPC To make the partial search functionality accessible through the API, you can wrap the search logic in a stored procedure. After creating this function, you can invoke it from your application using the SDK for your platform. Here's an example: This function takes a prefix parameter and returns all books where the title contains a word starting with that prefix. The `:*` operator is used to denote a prefix match in the `to_tsquery()` function. ## Handling spaces in queries When you want the search term to include a phrase or multiple words, you can concatenate words using a `+` as a placeholder for space: ```sql select * from search_books_by_title_prefix('Little+Puppy'); ``` ## Creating indexes Now that we have Full Text Search working, let's create an `index`. This will allow Postgres to "build" the documents preemptively so that they don't need to be created at the time we execute the query. This will make our queries much faster. ### Searchable columns Let's create a new column `fts` inside the `books` table to store the searchable index of the `title` and `description` columns. We can use a special feature of Postgres called [Generated Columns](https://www.postgresql.org/docs/current/ddl-generated-columns.html) to ensure that the index is updated any time the values in the `title` and `description` columns change. ### Search using the new column Now that we've created and populated our index, we can search it using the same techniques as before: ## Query operators Visit [Postgres: Text Search Functions and Operators](https://www.postgresql.org/docs/current/functions-textsearch.html) to learn about additional query operators you can use to do more advanced `full text queries`, such as: ### Proximity: `<->` \[#proximity] The proximity symbol is useful for searching for terms that are a certain "distance" apart. For example, to find the phrase `big dreams`, where the a match for "big" is followed immediately by a match for "dreams": We can also use the `<->` to find words within a certain distance of each other. For example to find `year` and `school` within 2 words of each other: ### Negation: `!` \[#negation] The negation symbol can be used to find phrases which *don't* contain a search term. For example, to find records that have the word `big` but not `little`: ## Resources * [Postgres: Text Search Functions and Operators](https://www.postgresql.org/docs/12/functions-textsearch.html) # Database Functions Postgres has built-in support for [SQL functions](https://www.postgresql.org/docs/current/sql-createfunction.html). These functions live inside your database, and they can be [used with the API](../../reference/javascript/rpc). ## Quick demo ## Getting started Supabase provides several options for creating database functions. You can use the Dashboard or create them directly using SQL. We provide a SQL editor within the Dashboard, or you can [connect](../../guides/database/connecting-to-postgres) to your database and run the SQL queries yourself. 1. Go to the "SQL editor" section. 2. Click "New Query". 3. Enter the SQL to create or replace your Database function. 4. Click "Run" or cmd+enter (ctrl+enter). ## Simple functions Let's create a basic Database Function which returns a string "hello world". ```sql create or replace function hello_world() -- 1 returns text -- 2 language sql -- 3 as $$ -- 4 select 'hello world'; -- 5 $$; --6 ``` After the Function is created, we have several ways of "executing" the function - either directly inside the database using SQL, or with one of the client libraries. ## Returning data sets Database Functions can also return data sets from [Tables](../../guides/database/tables) or Views. For example, if we had a database with some Star Wars data inside: We could create a function which returns all the planets: ```sql create or replace function get_planets() returns setof planets language sql as $$ select * from planets; $$; ``` Because this function returns a table set, we can also apply filters and selectors. For example, if we only wanted the first planet: ## Passing parameters Let's create a Function to insert a new planet into the `planets` table and return the new ID. Note that this time we're using the `plpgsql` language. ```sql create or replace function add_planet(name text) returns bigint language plpgsql as $$ declare new_row bigint; begin insert into planets(name) values (add_planet.name) returning id into new_row; return new_row; end; $$; ``` Once again, you can execute this function either inside your database using a `select` query, or with the client libraries: ## Suggestions ### Database Functions vs Edge Functions For data-intensive operations, use Database Functions, which are executed within your database and can be called remotely using the [REST and GraphQL API](../api). For use-cases which require low-latency, use [Edge Functions](../../guides/functions), which are globally-distributed and can be written in Typescript. ### Security `definer` vs `invoker` Postgres allows you to specify whether you want the function to be executed as the user *calling* the function (`invoker`), or as the *creator* of the function (`definer`). For example: ```sql create function hello_world() returns text language plpgsql security definer set search_path = '' as $$ begin select 'hello world'; end; $$; ``` It is best practice to use `security invoker` (which is also the default). If you ever use `security definer`, you *must* set the `search_path`. If you use an empty search path (`search_path = ''`), you must explicitly state the schema for every relation in the function body (e.g. `from public.table`). This limits the potential damage if you allow access to schemas which the user executing the function should not have. ### Function privileges By default, database functions can be executed by any role. There are two main ways to restrict this: 1. On a case-by-case basis. Specifically revoke permissions for functions you want to protect. Execution needs to be revoked for both `public` and the role you're restricting: ```sql revoke execute on function public.hello_world from public; revoke execute on function public.hello_world from anon; ``` 2. Restrict function execution by default. Specifically *grant* access when you want a function to be executable by a specific role. To restrict all existing functions, revoke execution permissions from both `public` *and* the role you want to restrict: ```sql revoke execute on all functions in schema public from public; revoke execute on all functions in schema public from anon, authenticated; ``` To restrict all new functions, change the default privileges for both `public` *and* the role you want to restrict: ```sql alter default privileges in schema public revoke execute on functions from public; alter default privileges in schema public revoke execute on functions from anon, authenticated; ``` You can then regrant permissions for a specific function to a specific role: ```sql grant execute on function public.hello_world to authenticated; ``` ### Debugging functions You can add logs to help you debug functions. This is especially recommended for complex functions. Good targets to log include: * Values of (non-sensitive) variables * Returned results from queries #### General logging To create custom logs in the [Dashboard's Postgres Logs](https://supabase.com/dashboard/project/_/logs/postgres-logs), you can use the `raise` keyword. By default, there are 3 observed severity levels: * `log` * `warning` * `exception` (error level) ```sql create function logging_example( log_message text, warning_message text, error_message text ) returns void language plpgsql as $$ begin raise log 'logging message: %', log_message; raise warning 'logging warning: %', warning_message; -- immediately ends function and reverts transaction raise exception 'logging error: %', error_message; end; $$; select logging_example('LOGGED MESSAGE', 'WARNING MESSAGE', 'ERROR MESSAGE'); ``` #### Error handling You can create custom errors with the `raise exception` keywords. A common pattern is to throw an error when a variable doesn't meet a condition: ```sql create or replace function error_if_null(some_val text) returns text language plpgsql as $$ begin -- error if some_val is null if some_val is null then raise exception 'some_val should not be NULL'; end if; -- return some_val if it is not null return some_val; end; $$; select error_if_null(null); ``` Value checking is common, so Postgres provides a shorthand: the `assert` keyword. It uses the following format: ```sql -- throw error when condition is false assert , 'message'; ``` Below is an example ```sql create function assert_example(name text) returns uuid language plpgsql as $$ declare student_id uuid; begin -- save a user's id into the user_id variable select id into student_id from attendance_table where student = name; -- throw an error if the student_id is null assert student_id is not null, 'assert_example() ERROR: student not found'; -- otherwise, return the user's id return student_id; end; $$; select assert_example('Harry Potter'); ``` Error messages can also be captured and modified with the `exception` keyword: ```sql create function error_example() returns void language plpgsql as $$ begin -- fails: cannot read from nonexistent table select * from table_that_does_not_exist; exception when others then raise exception 'An error occurred in function : %', sqlerrm; end; $$; ``` #### Advanced logging For more complex functions or complicated debugging, try logging: * Formatted variables * Individual rows * Start and end of function calls ```sql create or replace function advanced_example(num int default 10) returns text language plpgsql as $$ declare var1 int := 20; var2 text; begin -- Logging start of function raise log 'logging start of function call: (%)', (select now()); -- Logging a variable from a SELECT query select col_1 into var1 from some_table limit 1; raise log 'logging a variable (%)', var1; -- It is also possible to avoid using variables, by returning the values of your query to the log raise log 'logging a query with a single return value(%)', (select col_1 from some_table limit 1); -- If necessary, you can even log an entire row as JSON raise log 'logging an entire row as JSON (%)', (select to_jsonb(some_table.*) from some_table limit 1); -- When using INSERT or UPDATE, the new value(s) can be returned -- into a variable. -- When using DELETE, the deleted value(s) can be returned. -- All three operations use "RETURNING value(s) INTO variable(s)" syntax insert into some_table (col_2) values ('new val') returning col_2 into var2; raise log 'logging a value from an INSERT (%)', var2; return var1 || ',' || var2; exception -- Handle exceptions here if needed when others then raise exception 'An error occurred in function : %', sqlerrm; end; $$; select advanced_example(); ``` ## Resources * Official Client libraries: [JavaScript](../../reference/javascript/rpc) and [Flutter](../../reference/dart/rpc) * Community client libraries: [github.com/supabase-community](https://github.com/supabase-community) * Postgres Official Docs: [Chapter 9. Functions and Operators](https://www.postgresql.org/docs/current/functions.html) * Postgres Reference: [CREATE FUNCTION](https://www.postgresql.org/docs/9.1/sql-createfunction.html) ## Deep dive ### Create Database Functions ### Call Database Functions using JavaScript ### Using Database Functions to call an external API # Hardening the Data API Your database's automatically generated Data API exposes the `public` schema by default. If your `public` schema is used by other tools as a default space, you might want to lock down this schema. This helps prevent accidental exposure of data that's automatically added to `public`. There are two levels of security hardening for the Data API: * Disabling the Data API entirely. This is recommended if you *never* need to access your database via Supabase client libraries or the REST and GraphQL endpoints. * Removing the `public` schema from the Data API and replacing it with a custom schema (such as `api`). ## Disabling the Data API You can disable the Data API entirely if you never intend to use the Supabase client libraries or the REST and GraphQL data endpoints. For example, if you only access your database via a direct connection on the server, disabling the Data API gives you the greatest layer of protection. 1. Go to [API Settings](/dashboard/project/_/settings/api) in the Supabase Dashboard. 2. Under **Data API Settings**, toggle **Enable Data API** off. ## Exposing a custom schema instead of `public` If you want to use the Data API but with increased security, you can expose a custom schema instead of `public`. By not using `public`, which is often used as a default space and has laxer default permissions, you get more conscious control over your exposed data. Any data, views, or functions that should be exposed need to be deliberately put within your custom schema (which we will call `api`), rather than ending up there by default. ### Step 1: Remove `public` from exposed schemas 1. Go to [**API Settings**](/dashboard/project/_/settings/api) in the Supabase Dashboard. 2. Under **Data API Settings**, remove `public` from **Exposed schemas**. Also remove `public` from **Extra search path**. 3. Click **Save**. 4. Go to [**Database Extensions**](/dashboard/project/_/database/extensions) and disable the `pg_graphql` extension. ### Step 2: Create an `api` schema and expose it 1. Connect to your database. You can use `psql`, the [Supabase SQL Editor](/dashboard/project/_/sql), or the Postgres client of your choice. 2. Create a new schema named `api`: ```sql create schema if not exists api; ``` 3. Grant the `anon` and `authenticated` roles usage on this schema. ```sql grant usage on schema api to anon, authenticated; ``` 4. Go to [API Settings](/dashboard/project/_/settings/api) in the Supabase Dashboard. 5. Under **Data API Settings**, add `api` to **Exposed schemas**. Make sure it is the first schema in the list, so that it will be searched first by default. 6. Under these new settings, `anon` and `authenticated` can execute functions defined in the `api` schema, but they have no automatic permissions on any tables. On a table-by-table basis, you can grant them permissions. For example: ```sql grant select on table api. to anon; grant select, insert, update, delete on table api. to authenticated; ``` # Import data into Supabase You can import data into Supabase in multiple ways. The best method depends on your data size and app requirements. If you're working with small datasets in development, you can experiment quickly using CSV import in the Supabase dashboard. If you're working with a large dataset in production, you should plan your data import to minimize app latency and ensure data integrity. ## How to import data into Supabase You have multiple options for importing your data into Supabase: 1. [CSV import via the Supabase dashboard](#option-1-csv-import-via-supabase-dashboard) 2. [Bulk import using `pgloader`](#option-2-bulk-import-using-pgloader) 3. [Using the Postgres `COPY` command](#option-3-using-postgres-copy-command) 4. [Using the Supabase API](#option-4-using-the-supabase-api) ### Option 1: CSV import via Supabase dashboard Supabase dashboard provides a user-friendly way to import data. However, for very large datasets, this method may not be the most efficient choice, given the size limit is 100MB. It's generally better suited for smaller datasets and quick data imports. Consider using alternative methods like pgloader for large-scale data imports. 1. Navigate to the relevant table in the [Table Editor.](/dashboard/project/_/editor) 2. Click on “Insert” then choose "Import Data from CSV" and follow the on-screen instructions to upload your CSV file. ### Option 2: Bulk import using pgloader [pgloader](https://pgloader.io/) is a powerful tool for efficiently importing data into a Postgres database that supports a wide range of source database engines, including MySQL and MS SQL. You can use it in conjunction with Supabase by following these steps: 1. Install pgloader on your local machine or a server. For more info, you can refer to the [official pgloader installation page](https://pgloader.readthedocs.io/en/latest/install.html). ```bash $ apt-get install pgloader ``` 2. Create a configuration file that specifies the source data and the target Supabase database (e.g., config.load). Here's an example configuration file: ```sql LOAD DATABASE FROM sourcedb://USER:PASSWORD@HOST/SOURCE_DB INTO postgres://postgres.xxxx:password@xxxx.pooler.supabase.com:6543/postgres ALTER SCHEMA 'public' OWNER TO 'postgres'; set wal_buffers = '64MB', max_wal_senders = 0, statement_timeout = 0, work_mem to '2GB'; ``` Customize the source and Supabase database URL and options to fit your specific use case: * `wal_buffers`: This parameter is set to '64MB' to allocate 64 megabytes of memory for write-ahead logging buffers. A larger value can help improve write performance by caching more data in memory before writing it to disk. This can be useful during data import operations to speed up the writing of transaction logs. * `max_wal_senders`: It is set to 0, to disable replication connections. This is done during the data import process to prevent replication-related conflicts and issues. * `statement_timeout`: The value is set to 0, which means it's disabled, allowing SQL statements to run without a time limit. * `work_mem`: It is set to '2GB', allocating 2 GB of memory for query operations. This enhances the performance of complex queries by allowing larger in-memory datasets. 3. Run pgloader with the configuration file. ```jsx pgloader config.load ``` For databases using the Postgres engine, we recommend using the [pg\_dump](https://www.postgresql.org/docs/current/app-pgdump.html) and [psql](https://www.postgresql.org/docs/current/app-psql.html) command line tools. ### Option 3: Using Postgres copy command Read more about [Bulk data loading.](/docs/guides/database/tables#bulk-data-loading) ### Option 4: Using the Supabase API The Supabase API allows you to programmatically import data into your tables. You can use various client libraries to interact with the API and perform data import operations. This approach is useful when you need to automate data imports, and it gives you fine-grained control over the process. Refer to our [API guide](/docs/guides/api) for more details. ## Preparing to import data Large data imports can affect your database performance. Failed imports can also cause data corruption. Importing data is a safe and common operation, but you should plan ahead if you're importing a lot of data, or if you're working in a production environment. ### 1. Back up your data Backups help you restore your data if something goes wrong. Databases on Pro, Team and Enterprise Plans are automatically backed up on schedule, but you can also take your own backup. See [Database Backups](/docs/guides/platform/backups) for more information. ### 2. Increase statement timeouts By default, Supabase enforces query statement timeouts to ensure fair resource allocation and prevent long-running queries from affecting the overall system. When importing large datasets, you may encounter timeouts. To address this: * **Increase the Statement Timeout**: You can adjust the statement timeout for your session or connection to accommodate longer-running queries. Be cautious when doing this, as excessively long queries can negatively impact system performance. Read more about [Statement Timeouts](/docs/guides/database/postgres/configuration). ### 3. Estimate your required disk size Large datasets consume disk space. Ensure your Supabase project has sufficient disk capacity to accommodate the imported data. If you know how big your database is going to be, you can manually increase the size in your [projects database settings](/dashboard/project/_/settings/database). Read more about [disk management](/docs/guides/platform/database-size#disk-management). ### 4. Disable triggers When importing large datasets, it's often beneficial to disable triggers temporarily. Triggers can significantly slow down the import process, especially if they involve complex logic or referential integrity checks. After the import, you can re-enable the triggers. To disable triggers, use the following SQL commands: ```sql -- Disable triggers on a specific table ALTER TABLE table_name DISABLE TRIGGER ALL; -- To re-enable triggers ALTER TABLE table_name ENABLE TRIGGER ALL; ``` ### 5. Rebuild indices after data import is complete Indexing is crucial for query performance, but building indices while importing a large dataset can be time-consuming. Consider building or rebuilding indices after the data import is complete. This approach can significantly speed up the import process and reduce the overall time required. To build an index after the data import: ```sql -- Create an index on a table create index index_name on table_name (column_name); ``` Read more about [Managing Indexes in Postgres](/docs/guides/database/postgres/indexes). # Debugging and monitoring Database performance is a large topic and many factors can contribute. Some of the most common causes of poor performance include: * An inefficiently designed schema * Inefficiently designed queries * A lack of indexes causing slower than required queries over large tables * Unused indexes causing slow `INSERT`, `UPDATE` and `DELETE` operations * Not enough compute resources, such as memory, causing your database to go to disk for results too often * Lock contention from multiple queries operating on highly utilized tables * Large amount of bloat on your tables causing poor query planning You can examine your database and queries for these issues using either the [Supabase CLI](/docs/guides/local-development/cli/getting-started) or SQL. ## Using the CLI The Supabase CLI comes with a range of tools to help inspect your Postgres instances for potential issues. The CLI gets the information from . Therefore, most tools provided are compatible with any Postgres databases regardless if they are a Supabase project or not. You can find installation instructions for the the Supabase CLI . ### The `inspect db` command The inspection tools for your Postgres database are under then `inspect db` command. You can get a full list of available commands by running `supabase inspect db help`. $ supabase inspect db help Tools to inspect your Supabase database Usage: supabase inspect db [command] Available Commands: bloat Estimates space allocated to a relation that is full of dead tuples blocking Show queries that are holding locks and the queries that are waiting for them to be released cache-hit Show cache hit rates for tables and indices ... ### Connect to any Postgres database Most inspection commands are Postgres agnostic. You can run inspection routines on any Postgres database even if it is not a Supabase project by providing a connection string via `--db-url`. For example you can connect to your local Postgres instance: supabase --db-url postgresql://postgres:postgres@localhost:5432/postgres inspect db bloat ### Connect to a Supabase instance Working with Supabase, you can link the Supabase CLI with your project: supabase link --project-ref Then the CLI will automatically connect to your Supabase project whenever you are in the project folder and you no longer need to provide `—db-url`. ### Inspection commands Below are the `db` inspection commands provided, grouped by different use cases. #### Disk storage These commands are handy if you are running low on disk storage: * [bloat](/docs/reference/cli/supabase-inspect-db-bloat) - estimates the amount of wasted space * [vacuum-stats](/docs/reference/cli/supabase-inspect-db-vacuum-stats) - gives information on waste collection routines * [table-record-counts](/docs/reference/cli/supabase-inspect-db-table-record-counts) - estimates the number of records per table * [table-sizes](/docs/reference/cli/supabase-inspect-db-table-sizes) - shows the sizes of tables * [index-sizes](/docs/reference/cli/supabase-inspect-db-index-sizes) - shows the sizes of individual index * [table-index-sizes](/docs/reference/cli/supabase-inspect-db-table-index-sizes) - shows the sizes of indexes for each table #### Query performance The commands below are useful if your Postgres database consumes a lot of resources like CPU, RAM or Disk IO. You can also use them to investigate slow queries. * [cache-hit](/docs/reference/cli/supabase-inspect-db-cache-hit) - shows how efficient your cache usage is overall * [unused-indexes](/docs/reference/cli/supabase-inspect-db-unused-indexes) - shows indexes with low index scans * [index-usage](/docs/reference/cli/supabase-inspect-db-index-usage) - shows information about the efficiency of indexes * [seq-scans](/docs/reference/cli/supabase-inspect-db-seq-scans) - show number of sequential scans recorded against all tables * [long-running-queries](/docs/reference/cli/supabase-inspect-db-long-running-queries) - shows long running queries that are executing right now * [outliers](/docs/reference/cli/supabase-inspect-db-outliers) - shows queries with high execution time but low call count and queries with high proportion of execution time spent on synchronous I/O #### Locks * [locks](/docs/reference/cli/supabase-inspect-db-locks) - shows statements which have taken out an exclusive lock on a relation * [blocking](/docs/reference/cli/supabase-inspect-db-blocking) - shows statements that are waiting for locks to be released #### Connections * [role-connections](/docs/reference/cli/supabase-inspect-db-role-connections) - shows number of active connections for all database roles (Supabase-specific command) * [replication-slots](/docs/reference/cli/supabase-inspect-db-replication-slots) - shows information about replication slots on the database ### Notes on `pg_stat_statements` Following commands require `pg_stat_statements` to be enabled: calls, locks, cache-hit, blocking, unused-indexes, index-usage, bloat, outliers, table-record-counts, replication-slots, seq-scans, vacuum-stats, long-running-queries. When using `pg_stat_statements` also take note that it only stores the latest 5,000 statements. Moreover, consider resetting the analysis after optimizing any queries by running `select pg_stat_statements_reset();` Learn more about pg\_stats [here](https://supabase.com/docs/guides/database/extensions/pg_stat_statements). ## Using SQL ### Postgres cumulative statistics system Postgres collects data about its own operations using the [cumulative statistics system](https://www.postgresql.org/docs/current/monitoring-stats.html). In addition to this, every Supabase project has the [pg\_stat\_statements extension](/docs/guides/database/extensions/pg_stat_statements) enabled by default. This extension records query execution performance details and is the best way to find inefficient queries. This information can be combined with the Postgres query plan analyzer to develop more efficient queries. Here are some example queries to get you started. ### Most frequently called queries ```sql select auth.rolname, statements.query, statements.calls, -- -- Postgres 13, 14, 15 statements.total_exec_time + statements.total_plan_time as total_time, statements.min_exec_time + statements.min_plan_time as min_time, statements.max_exec_time + statements.max_plan_time as max_time, statements.mean_exec_time + statements.mean_plan_time as mean_time, -- -- Postgres <= 12 -- total_time, -- min_time, -- max_time, -- mean_time, statements.rows / statements.calls as avg_rows from pg_stat_statements as statements inner join pg_authid as auth on statements.userid = auth.oid order by statements.calls desc limit 100; ``` This query shows: * query statistics, ordered by the number of times each query has been executed * the role that ran the query * the number of times it has been called * the average number of rows returned * the cumulative total time the query has spent running * the min, max and mean query times. This provides useful information about the queries you run most frequently. Queries that have high `max_time` or `mean_time` times and are being called often can be good candidates for optimization. ### Slowest queries by execution time ```sql select auth.rolname, statements.query, statements.calls, -- -- Postgres 13, 14, 15 statements.total_exec_time + statements.total_plan_time as total_time, statements.min_exec_time + statements.min_plan_time as min_time, statements.max_exec_time + statements.max_plan_time as max_time, statements.mean_exec_time + statements.mean_plan_time as mean_time, -- -- Postgres <= 12 -- total_time, -- min_time, -- max_time, -- mean_time, statements.rows / statements.calls as avg_rows from pg_stat_statements as statements inner join pg_authid as auth on statements.userid = auth.oid order by max_time desc limit 100; ``` This query will show you statistics about queries ordered by the maximum execution time. It is similar to the query above ordered by calls, but this one highlights outliers that may have high executions times. Queries which have high or mean execution times are good candidates for optimization. ### Most time consuming queries ```sql select auth.rolname, statements.query, statements.calls, statements.total_exec_time + statements.total_plan_time as total_time, to_char( ( (statements.total_exec_time + statements.total_plan_time) / sum( statements.total_exec_time + statements.total_plan_time ) over () ) * 100, 'FM90D0' ) || '%' as prop_total_time from pg_stat_statements as statements inner join pg_authid as auth on statements.userid = auth.oid order by total_time desc limit 100; ``` This query will show you statistics about queries ordered by the cumulative total execution time. It shows the total time the query has spent running as well as the proportion of total execution time the query has taken up. Queries which are the most time consuming are not necessarily bad, you may have a very efficient and frequently ran queries that end up taking a large total % time, but it can be useful to help spot queries that are taking up more time than they should. ### Hit rate Generally for most applications a small percentage of data is accessed more regularly than the rest. To make sure that your regularly accessed data is available, Postgres tracks your data access patterns and keeps this in its [shared\_buffers](https://www.postgresql.org/docs/15/runtime-config-resource.html#RUNTIME-CONFIG-RESOURCE-MEMORY) cache. Applications with lower cache hit rates generally perform more poorly since they have to hit the disk to get results rather than serving them from memory. Very poor hit rates can also cause you to burst past your [Disk IO limits](./compute-add-ons#disk-io) causing significant performance issues. You can view your cache and index hit rate by executing the following query: ```sql select 'index hit rate' as name, (sum(idx_blks_hit)) / nullif(sum(idx_blks_hit + idx_blks_read), 0) * 100 as ratio from pg_statio_user_indexes union all select 'table hit rate' as name, sum(heap_blks_hit) / nullif(sum(heap_blks_hit) + sum(heap_blks_read), 0) * 100 as ratio from pg_statio_user_tables; ``` This shows the ratio of data blocks fetched from the Postgres [shared\_buffers](https://www.postgresql.org/docs/15/runtime-config-resource.html#RUNTIME-CONFIG-RESOURCE-MEMORY) cache against the data blocks that were read from disk/OS cache. If either of your index or table hit rate are < 99% then this can indicate your compute plan is too small for your current workload and you would benefit from more memory. [Upgrading your compute](./compute-add-ons) is easy and can be done from your [project dashboard](https://supabase.com/dashboard/project/_/settings/compute-and-disk). ### Optimizing poor performing queries Postgres has built in tooling to help you optimize poorly performing queries. You can use the [query plan analyzer](https://www.postgresql.org/docs/current/sql-explain.html) on any expensive queries that you have identified: ```sql explain analyze ; ``` When you include `analyze` in the explain statement, the database attempts to execute the query and provides a detailed query plan along with actual execution times. So, be careful using `explain analyze` with `insert`/`update`/`delete` queries, because the query will actually run, and could have unintended side-effects. If you run just `explain` without the `analyze` keyword, the database will only perform query planning without actually executing the query. This approach can be beneficial when you want to inspect the query plan without affecting the database or if you encounter timeouts in your queries. Using the query plan analyzer to optimize your queries is a large topic, with a number of online resources available: * [Official docs.](https://www.postgresql.org/docs/current/using-explain.html) * [The Art of PostgreSQL.](https://theartofpostgresql.com/explain-plan-visualizer/) * [Postgres Wiki.](https://wiki.postgresql.org/wiki/Using_EXPLAIN) * [Enterprise DB.](https://www.enterprisedb.com/blog/postgresql-query-optimization-performance-tuning-with-explain-analyze) You can pair the information available from `pg_stat_statements` with the detailed system metrics available [via your metrics endpoint](../platform/metrics) to better understand the behavior of your DB and the queries you're executing against it. # Querying Joins and Nested tables The data APIs automatically detect relationships between Postgres tables. Since Postgres is a relational database, this is a very common scenario. ## One-to-many joins Let's use an example database that stores `orchestral_sections` and `instruments`: The APIs will automatically detect relationships based on the foreign keys: ## Many-to-many joins The data APIs will detect many-to-many joins. For example, if you have a database which stored teams of users (where each user could belong to many teams): ```sql create table users ( "id" serial primary key, "name" text ); create table teams ( "id" serial primary key, "team_name" text ); create table members ( "user_id" int references users, "team_id" int references teams, primary key (user_id, team_id) ); ``` In these cases you don't need to explicitly define the joining table (members). If we wanted to fetch all the teams and the members in each team: ## Specifying the `ON` clause for joins with multiple foreign keys For example, if you have a project that tracks when employees check in and out of work shifts: ```sql -- Employees create table users ( "id" serial primary key, "name" text ); -- Badge scans create table scans ( "id" serial primary key, "user_id" int references users, "badge_scan_time" timestamp ); -- Work shifts create table shifts ( "id" serial primary key, "user_id" int references users, "scan_id_start" int references scans, -- clocking in "scan_id_end" int references scans, -- clocking out "attendance_status" text ); ``` In this case, you need to explicitly define the join because the joining column on `shifts` is ambiguous as they are both referencing the `scans` table. To fetch all the `shifts` with `scan_id_start` and `scan_id_end` related to a specific `scan`, use the following syntax: # Managing JSON and unstructured data Using the JSON data type in Postgres. Postgres supports storing and querying unstructured data. ## JSON vs JSONB Postgres supports two types of JSON columns: `json` (stored as a string) and `jsonb` (stored as a binary). The recommended type is `jsonb` for almost all cases. * `json` stores an exact copy of the input text. Database functions must reparse the content on each execution. * `jsonb` stores database in a decomposed binary format. While this makes it slightly slower to input due to added conversion overhead, it is significantly faster to process, since no reparsing is needed. ## When to use JSON/JSONB Generally you should use a `jsonb` column when you have data that is unstructured or has a variable schema. For example, if you wanted to store responses for various webhooks, you might not know the format of the response when creating the table. Instead, you could store the `payload` as a `jsonb` object in a single column. Don't go overboard with `json/jsonb` columns. They are a useful tool, but most of the benefits of a relational database come from the ability to query and join structured data, and the referential integrity that brings. ## Create JSONB columns `json/jsonb` is just another "data type" for Postgres columns. You can create a `jsonb` column in the same way you would create a `text` or `int` column: ## Inserting JSON data You can insert JSON data in the same way that you insert any other data. The data must be valid JSON. ## Query JSON data Querying JSON data is similar to querying other data, with a few other features to access nested values. Postgres support a range of [JSON functions and operators](https://www.postgresql.org/docs/current/functions-json.html). For example, the `->` operator returns values as `jsonb` data. If you want the data returned as `text`, use the `->>` operator. ## Validating JSON data Supabase provides the [`pg_jsonschema` extension](/docs/guides/database/extensions/pg_jsonschema) that adds the ability to validate `json` and `jsonb` data types against [JSON Schema](https://json-schema.org/) documents. Once you have enabled the extension, you can add a "check constraint" to your table to validate the JSON data: ```sql create table customers ( id serial primary key, metadata json ); alter table customers add constraint check_metadata check ( json_matches_schema( '{ "type": "object", "properties": { "tags": { "type": "array", "items": { "type": "string", "maxLength": 16 } } } }', metadata ) ); ``` ## Resources * [Postgres: JSON Functions and Operators](https://www.postgresql.org/docs/current/functions-json.html) * [Postgres JSON types](https://www.postgresql.org/docs/current/datatype-json.html) # Connecting to Metabase [`Metabase`](https://www.metabase.com/) is an Open Source data visualization tool. You can use it to explore your data stored in Supabase. # OrioleDB Overview The [OrioleDB](https://www.orioledb.com/) Postgres extension provides a drop-in replacement storage engine for the default heap storage method. It is designed to improve Postgres' scalability and performance. OrioleDB addresses PostgreSQL's scalability limitations by removing bottlenecks in the shared memory cache under high concurrency. It also optimizes write-ahead-log (WAL) insertion through row-level WAL logging. These changes lead to significant improvements in the industry standard TPC-C benchmark, which approximates a real-world transactional workload. The following benchmark was performed on a c7g.metal instance and shows OrioleDB's performance outperforming the default Postgres heap method with a 3.3x speedup. ## Concepts ### Index-organized tables OrioleDB uses index-organized tables, where table data is stored in the index structure. This design eliminates the need for separate heap storage, reduces overhead and improves lookup performance for primary key queries. ### No buffer mapping In-memory pages are connected to the storage pages using direct links. This allows OrioleDB to bypass PostgreSQL's shared buffer pool and eliminate the associated complexity and contention in buffer mapping. ### Undo log Multi-Version Concurrency Control (MVCC) is implemented using an undo log. The undo log stores previous row versions and transaction information, which enables consistent reads while removing the need for table vacuuming completely. ### Copy-on-write checkpoints OrioleDB implements copy-on-write checkpoints to persist data efficiently. This approach writes only modified data during a checkpoint, reducing the I/O overhead compared to traditional Postgres checkpointing and allowing row-level WAL logging. ## Usage ### Creating OrioleDB project You can get started with OrioleDB by enabling the extension in your Supabase dashboard. To get started with OrioleDB you need to [create a new Supabase project](https://supabase.com/dashboard/new/_) and choose `OrioleDB Public Alpha` Postgres version. ### Creating tables To create a table using the OrioleDB storage engine just execute the standard `CREATE TABLE` statement. By default it will create a table using OrioleDB storage engine. For example: ```sql -- Create a table create table blog_post ( id int8 not null, title text not null, body text not null, author text not null, published_at timestamptz not null default CURRENT_TIMESTAMP, views bigint not null, primary key (id) ); ``` ### Creating indexes OrioleDB tables always have a primary key. If it wasn't defined explicitly, a hidden primary key is created using the `ctid` column. Additionally you can create secondary indexes. ```sql -- Create an index create index blog_post_published_at on blog_post (published_at); create index blog_post_views on blog_post (views) where (views > 1000); ``` ### Data manipulation You can query and modify data in OrioleDB tables using standard SQL statements, including `SELECT`, `INSERT`, `UPDATE`, `DELETE` and `INSERT ... ON CONFLICT`. ```sql INSERT INTO blog_post (id, title, body, author, views) VALUES (1, 'Hello, World!', 'This is my first blog post.', 'John Doe', 1000); SELECT * FROM blog_post ORDER BY published_at DESC LIMIT 10; id │ title │ body │ author │ published_at │ views ────┼───────────────┼─────────────────────────────┼──────────┼───────────────────────────────┼─────── 1 │ Hello, World! │ This is my first blog post. │ John Doe │ 2024-11-15 12:04:18.756824+01 │ 1000 ``` ### Viewing query plans You can see the execution plan using standard `EXPLAIN` statement. ```sql EXPLAIN SELECT * FROM blog_post ORDER BY published_at DESC LIMIT 10; QUERY PLAN ──────────────────────────────────────────────────────────────────────────────────────────────────────────── Limit (cost=0.15..1.67 rows=10 width=120) -> Index Scan Backward using blog_post_published_at on blog_post (cost=0.15..48.95 rows=320 width=120) EXPLAIN SELECT * FROM blog_post WHERE id = 1; QUERY PLAN ────────────────────────────────────────────────────────────────────────────────── Index Scan using blog_post_pkey on blog_post (cost=0.15..8.17 rows=1 width=120) Index Cond: (id = 1) EXPLAIN (ANALYZE, BUFFERS) SELECT * FROM blog_post ORDER BY published_at DESC LIMIT 10; QUERY PLAN ────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────── Limit (cost=0.15..1.67 rows=10 width=120) (actual time=0.052..0.054 rows=1 loops=1) -> Index Scan Backward using blog_post_published_at on blog_post (cost=0.15..48.95 rows=320 width=120) (actual time=0.050..0.052 rows=1 loops=1) Planning Time: 0.186 ms Execution Time: 0.088 ms ``` ## Resources * [Official OrioleDB documentation](https://www.orioledb.com/docs) * [OrioleDB GitHub repository](https://github.com/orioledb/orioledb) # Database Every Supabase project comes with a full [Postgres](https://www.postgresql.org/) database, a free and open source database which is considered one of the world's most stable and advanced databases. ## Features ### Table view You don't have to be a database expert to start using Supabase. Our table view makes Postgres as easy to use as a spreadsheet. ![Table View.](/docs/img/table-view.png) ### Relationships Dig into the relationships within your data. ### Clone tables You can duplicate your tables, just like you would inside a spreadsheet. ### The SQL editor Supabase comes with a SQL Editor. You can also save your favorite queries to run later! ### Additional features * Supabase extends Postgres with realtime functionality using our [Realtime Server](https://github.com/supabase/realtime). * Every project is a full Postgres database, with `postgres` level access. * Supabase manages your database backups. * Import data directly from a CSV or excel spreadsheet. ### Extensions To expand the functionality of your Postgres database, you can use extensions. You can enable Postgres extensions with the click of a button within the Supabase dashboard. [Learn more](/docs/guides/database/extensions) about all the extensions provided on Supabase. ## Terminology ### Postgres or PostgreSQL? PostgreSQL the database was derived from the POSTGRES Project, a package written at the University of California at Berkeley in 1986. This package included a query language called "PostQUEL". In 1994, Postgres95 was built on top of POSTGRES code, adding an SQL language interpreter as a replacement for PostQUEL. Eventually, Postgres95 was renamed to PostgreSQL to reflect the SQL query capability. After this, many people referred to it as Postgres since it's less prone to confusion. Supabase is all about simplicity, so we also refer to it as Postgres. ## Tips Read about resetting your database password [here](/docs/guides/database/managing-passwords) and changing the timezone of your server [here](/docs/guides/database/managing-timezones). ## Next steps * Read more about [Postgres](https://www.postgresql.org/about/) * Sign in: [supabase.com/dashboard](https://supabase.com/dashboard) # Partitioning tables Table partitioning is a technique that allows you to divide a large table into smaller, more manageable parts called “partitions”. Each partition contains a subset of the data based on a specified criteria, such as a range of values or a specific condition. Partitioning can significantly improve query performance and simplify data management for large datasets. ## Benefits of table partitioning * **Improved query performance:** allows queries to target specific partitions, reducing the amount of data scanned and improving query execution time. * **Scalability:** With partitioning, you can add or remove partitions as your data grows or changes, enabling better scalability and flexibility. * **Efficient data management:** simplifies tasks such as data loading, archiving, and deletion by operating on smaller partitions instead of the entire table. * **Enhanced maintenance operations:** can optimize vacuuming and indexing, leading to faster maintenance tasks. ## Partitioning methods Postgres supports various partitioning methods based on how you want to partition your data. The commonly used methods are: 1. **Range Partitioning**: Data is divided into partitions based on a specified range of values. For example, you can partition a sales table by date, where each partition represents a specific time range (e.g., one partition for each month). 2. **List Partitioning**: Data is divided into partitions based on a specified list of values. For instance, you can partition a customer table by region, where each partition contains customers from a specific region (e.g., one partition for customers in the US, another for customers in Europe). 3. **Hash Partitioning**: Data is distributed across partitions using a hash function. This method provides a way to evenly distribute data among partitions, which can be useful for load balancing. However, it doesn't allow direct querying based on specific values. ## Creating partitioned tables Let's consider an example of range partitioning for a sales table based on the order date. We'll create monthly partitions to store data for each month: ```sql create table sales ( id bigint generated by default as identity, order_date date not null, customer_id bigint, amount bigint, -- We need to include all the -- partitioning columns in constraints: primary key (order_date, id) ) partition by range (order_date); create table sales_2000_01 partition of sales for values from ('2000-01-01') to ('2000-02-01'); create table sales_2000_02 partition of sales for values from ('2000-02-01') to ('2000-03-01'); ``` To create a partitioned table you append `partition by range ()` to the table creation statement. The column that you are partitioning with *must* be included in any unique index, which is the reason why we specify a composite primary key here (`primary key (order_date, id)`). ## Querying partitioned tables To query a partitioned table, you have two options: 1. Querying the parent table 2. Querying specific partitions ### Querying the parent table When you query the parent table, Postgres automatically routes the query to the relevant partitions based on the conditions specified in the query. This allows you to retrieve data from all partitions simultaneously. Example: ```sql select * from sales where order_date >= '2000-01-01' and order_date < '2000-03-01'; ``` This query will retrieve data from both the `sales_2000_01` and `sales_2000_02` partitions. ### Querying specific partitions If you only need to retrieve data from a specific partition, you can directly query that partition instead of the parent table. This approach is useful when you want to target a specific range or condition within a partition. ```sql select * from sales_2000_02; ``` This query will retrieve data only from the `sales_2000_02` partition. ## When to partition your tables There is no real threshold to determine when you should use partitions. Partitions introduce complexity, and complexity should be avoided until it's needed. A few guidelines: * If you are considering performance, avoid partitions until you see performance degradation on non-partitioned tables. * If you are using partitions as a management tool, it's fine to create the partitions any time. * If you don't know how you should partition your data, then it's probably too early. ## Examples Here are simple examples for each of the partitioning types in Postgres. ### Range partitioning Let's consider a range partitioning example for a table that stores sales data based on the order date. We'll create monthly partitions to store data for each month. In this example, the **`sales`** table is partitioned into two partitions: **`sales_january`** and **`sales_february`**. The data in these partitions is based on the specified range of order dates: ```sql create table sales ( id bigint generated by default as identity, order_date date not null, customer_id bigint, amount bigint, -- We need to include all the -- partitioning columns in constraints: primary key (order_date, id) ) partition by range (order_date); create table sales_2000_01 partition of sales for values from ('2000-01-01') to ('2000-02-01'); create table sales_2000_02 partition of sales for values from ('2000-02-01') to ('2000-03-01'); ``` ### List partitioning Let's consider a list partitioning example for a table that stores customer data based on their region. We'll create partitions to store customers from different regions. In this example, the **`customers`** table is partitioned into two partitions: `customers_americas` and `customers_asia`. The data in these partitions is based on the specified list of regions: ```sql -- Create the partitioned table create table customers ( id bigint generated by default as identity, name text, country text, -- We need to include all the -- partitioning columns in constraints: primary key (country, id) ) partition by list(country); create table customers_americas partition of customers for values in ('US', 'CANADA'); create table customers_asia partition of customers for values in ('INDIA', 'CHINA', 'JAPAN'); ``` ### Hash partitioning You can use hash partitioning to evenly distribute data. In this example, the **`products`** table is partitioned into two partitions: `products_one` and `products_two`. The data is distributed across these partitions using a hash function: ```sql create table products ( id bigint generated by default as identity, name text, category text, price bigint ) partition by hash (id); create table products_one partition of products for values with (modulus 2, remainder 1); create table products_two partition of products for values with (modulus 2, remainder 0); ``` ## Other tools There are several other tools available for Postgres partitioning, most notably [pg\_partman](https://github.com/pgpartman/pg_partman). Native partitioning was introduced in Postgres 10 and is generally thought to have better performance. # 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. # Postgres.js ### Connecting with Postgres.js [Postgres.js](https://github.com/porsager/postgres) is a full-featured Postgres client for Node.js and Deno. # Cascade Deletes There are 5 options for foreign key constraint deletes: 1. **CASCADE:** When a row is deleted from the parent table, all related rows in the child tables are deleted as well. 2. **RESTRICT:** When a row is deleted from the parent table, the delete operation is aborted if there are any related rows in the child tables. 3. **SET NULL:** When a row is deleted from the parent table, the values of the foreign key columns in the child tables are set to NULL. 4. **SET DEFAULT:** When a row is deleted from the parent table, the values of the foreign key columns in the child tables are set to their default values. 5. **NO ACTION:** This option is similar to RESTRICT, but it also has the option to be “deferred” to the end of a transaction. This means that other cascading deletes can run first, and then this delete constraint will only throw an error if there is referenced data remaining *at the end of the transaction*. These options can be specified when defining a foreign key constraint using the "ON DELETE" clause. For example, the following SQL statement creates a foreign key constraint with the `CASCADE` option: ```sql alter table child_table add constraint fk_parent foreign key (parent_id) references parent_table (id) on delete cascade; ``` This means that when a row is deleted from the `parent_table`, all related rows in the `child_table` will be deleted as well. ## `RESTRICT` vs `NO ACTION` The difference between `NO ACTION` and `RESTRICT` is subtle and can be a bit confusing. Both `NO ACTION` and `RESTRICT` are used to prevent deletion of a row in a parent table if there are related rows in a child table. However, there is a subtle difference in how they behave. When a foreign key constraint is defined with the option `RESTRICT`, it means that if a row in the parent table is deleted, the database will immediately raise an error and prevent the deletion of the row in the parent table. The database will not delete, update or set to NULL any rows in the referenced tables. When a foreign key constraint is defined with the option `NO ACTION`, it means that if a row in the parent table is deleted, the database will also raise an error and prevent the deletion of the row in the parent table. However unlike `RESTRICT`, `NO ACTION` has the option defer the check using `INITIALLY DEFERRED`. This will only raise the above error *if* the referenced rows still exist at the end of the transaction. The difference from `RESTRICT` is that a constraint marked as `NO ACTION INITIALLY DEFERRED` is deferred until the end of the transaction, rather than running immediately. If, for example there is another foreign key constraint between the same tables marked as `CASCADE`, the cascade will occur first and delete the referenced rows, and no error will be thrown by the deferred constraint. Otherwise if there are still rows referencing the parent row by the end of the transaction, an error will be raised just like before. Just like `RESTRICT`, the database will not delete, update or set to NULL any rows in the referenced tables. In practice, you can use either `NO ACTION` or `RESTRICT` depending on your needs. `NO ACTION` is the default behavior if you do not specify anything. If you prefer to defer the check until the end of the transaction, use `NO ACTION INITIALLY DEFERRED`. ## Example Let's further illustrate the difference with an example. We'll use the following data: `grandparent` | id | name | | --- | --------- | | 1 | Elizabeth | `parent` | id | name | `parent_id` | | --- | ------- | ----------- | | 1 | Charles | 1 | | 2 | Diana | 1 | `child` | id | name | father | mother | | --- | ------- | ------ | ------ | | 1 | William | 1 | 2 | To create these tables and their data, we run: ```sql create table grandparent ( id serial primary key, name text ); create table parent ( id serial primary key, name text, parent_id integer references grandparent (id) on delete cascade ); create table child ( id serial primary key, name text, father integer references parent (id) on delete restrict ); insert into grandparent (id, name) values (1, 'Elizabeth'); insert into parent (id, name, parent_id) values (1, 'Charles', 1); insert into parent (id, name, parent_id) values (2, 'Diana', 1); -- We'll just link the father for now insert into child (id, name, father) values (1, 'William', 1); ``` ### `RESTRICT` `RESTRICT` will prevent a delete and raise an error: ```shell postgres=# delete from grandparent; ERROR: update or delete on table "parent" violates foreign key constraint "child_father_fkey" on table "child" DETAIL: Key (id)=(1) is still referenced from table "child". ``` Even though the foreign key constraint between parent and grandparent is `CASCADE`, the constraint between child and father is `RESTRICT`. Therefore an error is raised and no records are deleted. ### `NO ACTION` Let's change the child-father relationship to `NO ACTION`: ```sql alter table child drop constraint child_father_fkey; alter table child add constraint child_father_fkey foreign key (father) references parent (id) on delete no action; ``` We see that `NO ACTION` will also prevent a delete and raise an error: ```shell postgres=# delete from grandparent; ERROR: update or delete on table "parent" violates foreign key constraint "child_father_fkey" on table "child" DETAIL: Key (id)=(1) is still referenced from table "child". ``` ### `NO ACTION INITIALLY DEFERRED` We'll change the foreign key constraint between child and father to be `NO ACTION INITIALLY DEFERRED`: ```sql alter table child drop constraint child_father_fkey; alter table child add constraint child_father_fkey foreign key (father) references parent (id) on delete no action initially deferred; ``` Here you will see that `INITIALLY DEFFERED` seems to operate like `NO ACTION` or `RESTRICT`. When we run a delete, it seems to make no difference: ```shell postgres=# delete from grandparent; ERROR: update or delete on table "parent" violates foreign key constraint "child_father_fkey" on table "child" DETAIL: Key (id)=(1) is still referenced from table "child". ``` But, when we combine it with *other* constraints, then any other constraints take precedence. For example, let's run the same but add a `mother` column that has a `CASCADE` delete: ```sql alter table child add column mother integer references parent (id) on delete cascade; update child set mother = 2 where id = 1; ``` Then let's run a delete on the `grandparent` table: ```shell postgres=# delete from grandparent; DELETE 1 postgres=# select * from parent; id | name | parent_id ----+------+----------- (0 rows) postgres=# select * from child; id | name | father | mother ----+------+--------+-------- (0 rows) ``` The `mother` deletion took precedence over the `father`, and so William was deleted. After William was deleted, there was no reference to “Charles” and so he was free to be deleted, even though previously he wasn't (without `INITIALLY DEFERRED`). # Column Level Security PostgreSQL's [Row Level Security (RLS)](https://www.postgresql.org/docs/current/ddl-rowsecurity.html) gives you granular control over who can access rows of data. However, it doesn't give you control over which columns they can access within rows. Sometimes you want to restrict access to specific columns in your database. Column Level Privileges allows you to do just that. ## Policies at the row level Policies in Row Level Security (RLS) are used to restrict access to rows in a table. Think of them like adding a `WHERE` clause to every query. For example, let's assume you have a `posts` table with the following columns: * `id` * `user_id` * `title` * `content` * `created_at` * `updated_at` You can restrict updates to just the user who created it using [RLS](/docs/guides/auth#row-level-security), with the following policy: ```sql create policy "Allow update for owners" on posts for update using ((select auth.uid()) = user_id); ``` However, this gives the post owner full access to update the row, including all of the columns. ## Privileges at the column level To restrict access to columns, you can use [Privileges](https://www.postgresql.org/docs/current/ddl-priv.html). There are two types of privileges in Postgres: 1. **table-level**: Grants the privilege on all columns in the table. 2. **column-level** Grants the privilege on a specific column in the table. You can have both types of privileges on the same table. If you have both, and you revoke the column-level privilege, the table-level privilege will still be in effect. By default, our table will have a table-level `UPDATE` privilege, which means that the `authenticated` role can update all the columns in the table. ```sql revoke update on table public.posts from authenticated; grant update (title, content) on table public.posts to authenticated; ``` In the above example, we are revoking the table-level `UPDATE` privilege from the `authenticated` role and granting a column-level `UPDATE` privilege on just the `title` and `content` columns. If we want to restrict access to updating the `title` column: ```sql revoke update (title) on table public.posts from authenticated; ``` This time, we are revoking the column-level `UPDATE` privilege of the `title` column from the `authenticated` role. We didn't need to revoke the table-level `UPDATE` privilege because it's already revoked. ## Manage column privileges in the Dashboard You can view and edit the privileges in the [Supabase Studio](https://supabase.com/dashboard/project/_/database/column-privileges). ![Column level privileges](/docs/img/guides/privileges/column-level-privileges-2.png) ## Manage column privileges in migrations While you can manage privileges directly from the Dashboard, as your project grows you may want to manage them in your migrations. Read about database migrations in the [Local Development](https://supabase.com/docs/guides/deployment/database-migrations) guide. ## Considerations when using column-level privileges * If you turn off a column privilege you won't be able to use that column at all. * All operations (insert, update, delete) as well as using `select *` will fail. # Database configuration Updating the default configuration for your Postgres database. Postgres provides a set of sensible defaults for you database size. In some cases, these defaults can be updated. We do not recommend changing these defaults unless you know what you're doing. ## Timeouts See the [Timeouts](/docs/guides/database/postgres/timeouts) section. ## Statement optimization All Supabase projects come with the [`pg_stat_statements`](https://www.postgresql.org/docs/current/pgstatstatements.html) extension installed, which tracks planning and execution statistics for all statements executed against it. These statistics can be used in order to diagnose the performance of your project. This data can further be used in conjunction with the [`explain`](https://www.postgresql.org/docs/current/using-explain.html) functionality of Postgres to optimize your usage. ## Managing timezones Every Supabase database is set to UTC timezone by default. We strongly recommend keeping it this way, even if your users are in a different location. This is because it makes it much easier to calculate differences between timezones if you adopt the mental model that everything in your database is in UTC time. ### Change timezone ### Full list of timezones Get a full list of timezones supported by your database. This will return the following columns: * `name`: Time zone name * `abbrev`: Time zone abbreviation * `utc_offset`: Offset from UTC (positive means east of Greenwich) * `is_dst`: True if currently observing daylight savings ### Search for a specific timezone Use `ilike` (case insensitive search) to find specific timezones. # Custom Claims & Role-based Access Control (RBAC) Custom Claims are special attributes attached to a user that you can use to control access to portions of your application. For example: ```json { "user_role": "admin", "plan": "TRIAL", "user_level": 100, "group_name": "Super Guild!", "joined_on": "2022-05-20T14:28:18.217Z", "group_manager": false, "items": ["toothpick", "string", "ring"] } ``` To implement Role-Based Access Control (RBAC) with `custom claims`, use a [Custom Access Token Auth Hook](/docs/guides/auth/auth-hooks#hook-custom-access-token). This hook runs before a token is issued. You can use it to add additional claims to the user's JWT. This guide uses the [Slack Clone example](https://github.com/supabase/supabase/tree/master/examples/slack-clone/nextjs-slack-clone) to demonstrate how to add a `user_role` claim and use it in your [Row Level Security (RLS) policies](/docs/guides/database/postgres/row-level-security). ## Create a table to track user roles and permissions In this example, you will implement two user roles with specific permissions: * `moderator`: A moderator can delete all messages but not channels. * `admin`: An admin can delete all messages and channels. ```sql supabase/migrations/init.sql -- Custom types create type public.app_permission as enum ('channels.delete', 'messages.delete'); create type public.app_role as enum ('admin', 'moderator'); -- USER ROLES create table public.user_roles ( id bigint generated by default as identity primary key, user_id uuid references auth.users on delete cascade not null, role app_role not null, unique (user_id, role) ); comment on table public.user_roles is 'Application roles for each user.'; -- ROLE PERMISSIONS create table public.role_permissions ( id bigint generated by default as identity primary key, role app_role not null, permission app_permission not null, unique (role, permission) ); comment on table public.role_permissions is 'Application permissions for each role.'; ``` You can now manage your roles and permissions in SQL. For example, to add the mentioned roles and permissions from above, run: ```sql supabase/seed.sql insert into public.role_permissions (role, permission) values ('admin', 'channels.delete'), ('admin', 'messages.delete'), ('moderator', 'messages.delete'); ``` ## Create Auth Hook to apply user role The [Custom Access Token Auth Hook](/docs/guides/auth/auth-hooks#hook-custom-access-token) runs before a token is issued. You can use it to edit the JWT. ### Enable the hook In the dashboard, navigate to [`Authentication > Hooks (Beta)`](/dashboard/project/_/auth/hooks) and select the appropriate Postgres function from the dropdown menu. When developing locally, follow the [local development](/docs/guides/auth/auth-hooks#local-development) instructions. ## Accessing custom claims in RLS policies To utilize Role-Based Access Control (RBAC) in Row Level Security (RLS) policies, create an `authorize` method that reads the user's role from their JWT and checks the role's permissions: ```sql supabase/migrations/init.sql create or replace function public.authorize( requested_permission app_permission ) returns boolean as $$ declare bind_permissions int; user_role public.app_role; begin -- Fetch user role once and store it to reduce number of calls select (auth.jwt() ->> 'user_role')::public.app_role into user_role; select count(*) into bind_permissions from public.role_permissions where role_permissions.permission = requested_permission and role_permissions.role = user_role; return bind_permissions > 0; end; $$ language plpgsql stable security definer set search_path = ''; ``` You can then use the `authorize` method within your RLS policies. For example, to enable the desired delete access, you would add the following policies: ```sql create policy "Allow authorized delete access" on public.channels for delete to authenticated using ( (SELECT authorize('channels.delete')) ); create policy "Allow authorized delete access" on public.messages for delete to authenticated using ( (SELECT authorize('messages.delete')) ); ``` ## Accessing custom claims in your application The auth hook will only modify the access token JWT but not the auth response. Therefore, to access the custom claims in your application, e.g. your browser client, or server-side middleware, you will need to decode the `access_token` JWT on the auth session. In a JavaScript client application you can for example use the [`jwt-decode` package](https://www.npmjs.com/package/jwt-decode): ```js import { jwtDecode } from 'jwt-decode' const { subscription: authListener } = supabase.auth.onAuthStateChange(async (event, session) => { if (session) { const jwt = jwtDecode(session.access_token) const userRole = jwt.user_role } }) ``` For server-side logic you can use packages like [`express-jwt`](https://github.com/auth0/express-jwt), [`koa-jwt`](https://github.com/stiang/koa-jwt), [`PyJWT`](https://github.com/jpadilla/pyjwt), [dart\_jsonwebtoken](https://pub.dev/packages/dart_jsonwebtoken), [Microsoft.AspNetCore.Authentication.JwtBearer](https://www.nuget.org/packages/Microsoft.AspNetCore.Authentication.JwtBearer), etc. ## Conclusion You now have a robust system in place to manage user roles and permissions within your database that automatically propagates to Supabase Auth. ## More resources * [Auth Hooks](/docs/guides/auth/auth-hooks) * [Row Level Security](/docs/guides/database/postgres/row-level-security) * [RLS Functions](/docs/guides/database/postgres/row-level-security#using-functions) * [Next.js Slack Clone Example](https://github.com/supabase/supabase/tree/master/examples/slack-clone/nextjs-slack-clone) # Drop all tables in a PostgreSQL schema Execute the following query to drop all tables in a given schema. Replace `my-schema-name` with the name of your schema. In Supabase, the default schema is `public`. ```sql do $$ declare r record; begin for r in (select tablename from pg_tables where schemaname = 'my-schema-name') loop execute 'drop table if exists ' || quote_ident(r.tablename) || ' cascade'; end loop; end $$; ``` This query works by listing out all the tables in the given schema and then executing a `drop table` for each (hence the `for... loop`). You can run this query using the [SQL Editor](https://supabase.com/dashboard/project/_/sql) in the Supabase Dashboard, or via `psql` if you're [connecting directly to the database](/docs/guides/database/connecting-to-postgres#direct-connections). # Managing Enums in Postgres Enums in Postgres are a custom data type. They allow you to define a set of values (or labels) that a column can hold. They are useful when you have a fixed set of possible values for a column. ## Creating enums You can define a Postgres Enum using the `create type` statement. Here's an example: ```sql create type mood as enum ( 'happy', 'sad', 'excited', 'calm' ); ``` In this example, we've created an Enum called "mood" with four possible values. ## When to use enums There is a lot of overlap between Enums and foreign keys. Both can be used to define a set of values for a column. However, there are some advantages to using Enums: * Performance: You can query a single table instead of finding the value from a lookup table. * Simplicity: Generally the SQL is easier to read and write. There are also some disadvantages to using Enums: * Limited Flexibility: Adding and removing values requires modifying the database schema (i.e.: using migrations) rather than adding data to a table. * Maintenance Overhead: Enum types require ongoing maintenance. If your application's requirements change frequently, maintaining enums can become burdensome. In general you should only use Enums when the list of values is small, fixed, and unlikely to change often. Things like "a list of continents" or "a list of departments" are good candidates for Enums. ## Using enums in tables To use the Enum in a table, you can define a column with the Enum type. For example: ```sql create table person ( id serial primary key, name text, current_mood mood ); ``` Here, the `current_mood` column can only have values from the "mood" Enum. ### Inserting data with enums You can insert data into a table with Enum columns by specifying one of the Enum values: ```sql insert into person (name, current_mood) values ('Alice', 'happy'); ``` ### Querying data with enums When querying data, you can filter and compare Enum values as usual: ```sql select * from person where current_mood = 'sad'; ``` ## Managing enums You can manage your Enums using the `alter type` statement. Here are some examples: ### Updating enum values You can update the value of an Enum column: ```sql update person set current_mood = 'excited' where name = 'Alice'; ``` ### Adding enum values To add new values to an existing Postgres Enum, you can use the `ALTER TYPE` statement. Here's how you can do it: Let's say you have an existing Enum called `mood`, and you want to add a new value, `content`: ```sql alter type mood add value 'content'; ``` ### Removing enum values Even though it is possible, it is unsafe to remove enum values once they have been created. It's better to leave the enum value in place. ### Getting a list of enum values Check your existing Enum values by querying the enum\_range function: ```sql select enum_range(null::mood); ``` ## Resources * Official Postgres Docs: [Enumerated Types](https://www.postgresql.org/docs/current/datatype-enum.html) # Select first row for each group in PostgreSQL Given a table `seasons`: | id | team | points | | --- | :-------: | -----: | | 1 | Liverpool | 82 | | 2 | Liverpool | 84 | | 3 | Brighton | 34 | | 4 | Brighton | 28 | | 5 | Liverpool | 79 | We want to find the rows containing the maximum number of points *per team*. The expected output we want is: | id | team | points | | --- | :-------: | -----: | | 3 | Brighton | 34 | | 2 | Liverpool | 84 | From the [SQL Editor](https://supabase.com/dashboard/project/_/sql), you can run a query like: ```sql select distinct on (team) id, team, points from seasons order BY id, points desc, team; ``` The important bits here are: * The `desc` keyword to order the `points` from highest to lowest. * The `distinct` keyword that tells Postgres to only return a single row per team. This query can also be executed via `psql` or any other query editor if you prefer to [connect directly to the database](/docs/guides/database/connecting-to-postgres#direct-connections). # Managing Indexes in PostgreSQL An index makes your Postgres queries faster. The index is like a "table of contents" for your data - a reference list which allows queries to quickly locate a row in a given table without needing to scan the entire table (which in large tables can take a long time). Indexes can be structured in a few different ways. The type of index chosen depends on the values you are indexing. By far the most common index type, and the default in Postgres, is the B-Tree. A B-Tree is the generalized form of a binary search tree, where nodes can have more than two children. Even though indexes improve query performance, the Postgres query planner may not always make use of a given index when choosing which optimizations to make. Additionally indexes come with some overhead - additional writes and increased storage - so it's useful to understand how and when to use indexes, if at all. ## Create an index Let's take an example table: ```sql create table persons ( id bigint generated by default as identity primary key, age int, height int, weight int, name text, deceased boolean ); ``` We might want to frequently query users based on their age: ```sql select name from persons where age = 32; ``` Without an index, Postgres will scan every row in the table to find equality matches on age. You can verify this by doing an explain on the query: ```sql explain select name from persons where age = 32; ``` Outputs: Seq Scan on persons (cost=0.00..22.75 rows=x width=y) Filter: (age = 32) To add a simple B-Tree index you can run: ```sql create index idx_persons_age on persons (age); ``` Here is a simplified diagram of the index we just created (note that in practice, nodes actually have more than two children). You can see that in any large data set, traversing the index to locate a given value can be done in much less operations (O(log n)) than compared to scanning the table one value at a time from top to bottom (O(n)). ## Partial indexes If you are frequently querying a subset of rows then it may be more efficient to build a partial index. In our example, perhaps we only want to match on `age` where `deceased is false`. We could build a partial index: ```sql create index idx_living_persons_age on persons (age) where deceased is false; ``` ## Ordering indexes By default B-Tree indexes are sorted in ascending order, but sometimes you may want to provide a different ordering. Perhaps our application has a page featuring the top 10 oldest people. Here we would want to sort in descending order, and include `NULL` values last. For this we can use: ```sql create index idx_persons_age_desc on persons (age desc nulls last); ``` ## Reindexing After a while indexes can become stale and may need rebuilding. Postgres provides a `reindex` command for this, but due to Postgres locks being placed on the index during this process, you may want to make use of the `concurrent` keyword. ```sql reindex index concurrently idx_persons_age; ``` Alternatively you can reindex all indexes on a particular table: ```sql reindex table concurrently persons; ``` Take note that `reindex` can be used inside a transaction, but `reindex [index/table] concurrently` cannot. ## Index Advisor Indexes can improve query performance of your tables as they grow. The Supabase Dashboard offers an Index Advisor, which suggests potential indexes to add to your tables. For more information on the Index Advisor and its suggestions, see the [`index_advisor` extension](/docs/guides/database/extensions/index_advisor). To use the Dashboard Index Advisor: 1. Go to the [Query Performance](/dashboard/project/_/advisors/query-performance) page. 2. Click on a query to bring up the Details side panel. 3. Select the Indexes tab. 4. Enable Index Advisor if prompted. ### Understanding Index Advisor results The Indexes tab shows the existing indexes used in the selected query. Note that indexes suggested in the "New Index Recommendations" section may not be used when you create them. Postgres' query planner may intentionally ignore an available index if it determines that the query will be faster without. For example, on a small table, a sequential scan might be faster than an index scan. In that case, the planner will switch to using the index as the table size grows, helping to future proof the query. If additional indexes might improve your query, the Index Advisor shows the suggested indexes with the estimated improvement in startup and total costs: * Startup cost is the cost to fetch the first row * Total cost is the cost to fetch all the rows Costs are in arbitrary units, where a single sequential page read costs 1.0 units. # Roles, superuser access and unsupported operations Supabase provides the default `postgres` role to all instances deployed. Superuser access is not given as it allows destructive operations to be performed on the database. To ensure you are not impacted by this, additional privileges are granted to the `postgres` user to allow it to run some operations that are normally restricted to superusers. However, this does mean that some operations, that typically require `superuser` privileges, are not available on Supabase. These are documented below: ## Unsupported operations * `CREATE SUBSCRIPTION` * `CREATE EVENT TRIGGER` * `COPY ... FROM PROGRAM` * `ALTER USER ... WITH SUPERUSER` # Postgres Roles Managing access to your Postgres database and configuring permissions. Postgres manages database access permissions using the concept of roles. Generally you wouldn't use these roles for your own application - they are mostly for configuring *system access* to your database. If you want to configure *application access*, then you should use [Row Level Security](/docs/guides/database/postgres/row-level-security) (RLS). You can also implement [Role-based Access Control](/docs/guides/database/postgres/custom-claims-and-role-based-access-control-rbac) on top of RLS. ## Users vs roles In Postgres, roles can function as users or groups of users. Users are roles with login privileges, while groups (also known as role groups) are roles that don't have login privileges but can be used to manage permissions for multiple users. ## Creating roles You can create a role using the `create role` command: ```sql create role "role_name"; ``` ## Creating users Roles and users are essentially the same in Postgres, however if you want to use password-logins for a specific role, then you can use `WITH LOGIN PASSWORD`: ```sql create role "role_name" with login password 'extremely_secure_password'; ``` ## Passwords Your Postgres database is the core of your Supabase project, so it's important that every role has a strong, secure password at all times. Here are some tips for creating a secure password: * Use a password manager to generate it. * Make a long password (12 characters at least). * Don't use any common dictionary words. * Use both upper and lower case characters, numbers, and special symbols. ### Special symbols in passwords If you use special symbols in your Postgres password, you must remember to [percent-encode](https://en.wikipedia.org/wiki/Percent-encoding) your password later if using the Postgres connection string, for example, `postgresql://postgres.projectref:p%3Dword@aws-0-us-east-1.pooler.supabase.com:6543/postgres` ### Changing your project password When you created your project you were also asked to enter a password. This is actually the password for the `postgres` role in your database. You can update this from the Dashboard under the [database settings](https://supabase.com/dashboard/project/_/settings/database) page. You should *never* give this to third-party service unless you absolutely trust them. Instead, we recommend that you create a new user for every service that you want to give access too. This will also help you with debugging - you can see every query that each role is executing in your database within `pg_stat_statements`. Changing the password does not result in any downtime. All connected services, such as PostgREST, PgBouncer, and other Supabase managed services, are automatically updated to use the latest password to ensure availability. However, if you have any external services connecting to the Supabase database using hardcoded username/password credentials, a manual update will be required. ## Granting permissions Roles can be granted various permissions on database objects using the `GRANT` command. Permissions include `SELECT`, `INSERT`, `UPDATE`, and `DELETE`. You can configure access to almost any object inside your database - including tables, views, functions, and triggers. ## Revoking permissions Permissions can be revoked using the `REVOKE` command: ```sql REVOKE permission_type ON object_name FROM role_name; ``` ## Role hierarchy Roles can be organized in a hierarchy, where one role can inherit permissions from another. This simplifies permission management, as you can define permissions at a higher level and have them automatically apply to all child roles. ### Role inheritance To create a role hierarchy, you first need to create the parent and child roles. The child role will inherit permissions from its parent. Child roles can be added using the INHERIT option when creating the role: ```sql create role "child_role_name" inherit "parent_role_name"; ``` ### Preventing inheritance In some cases, you might want to prevent a role from having a child relationship (typically superuser roles). You can prevent inheritance relations using `NOINHERIT`: ```sql alter role "child_role_name" noinherit; ``` ## Supabase roles Postgres comes with a set of [predefined roles](https://www.postgresql.org/docs/current/predefined-roles.html). Supabase extends this with a default set of roles which are configured on your database when you start a new project: ### `postgres` The default Postgres role. This has admin privileges. ### `anon` For unauthenticated, public access. This is the role which the API (PostgREST) will use when a user *is not* logged in. ### `authenticator` A special role for the API (PostgREST). It has very limited access, and is used to validate a JWT and then "change into" another role determined by the JWT verification. ### `authenticated` For "authenticated access." This is the role which the API (PostgREST) will use when a user *is* logged in. ### `service_role` For elevated access. This role is used by the API (PostgREST) to bypass Row Level Security. ### `supabase_auth_admin` Used by the Auth middleware to connect to the database and run migration. Access is scoped to the `auth` schema. ### `supabase_storage_admin` Used by the Auth middleware to connect to the database and run migration. Access is scoped to the `storage` schema. ### `dashboard_user` For running commands via the Supabase UI. ### `supabase_admin` An internal role Supabase uses for administrative tasks, such as running upgrades and automations. ## Resources * Official Postgres docs: [Database Roles](https://www.postgresql.org/docs/current/database-roles.html) * Official Postgres docs: [Role Membership](https://www.postgresql.org/docs/current/role-membership.html) * Official Postgres docs: [Function Permissions](https://www.postgresql.org/docs/current/perm-functions.html) # Row Level Security Secure your data using Postgres Row Level Security. When you need granular authorization rules, nothing beats Postgres's [Row Level Security (RLS)](https://www.postgresql.org/docs/current/ddl-rowsecurity.html). ## Row Level Security in Supabase RLS is incredibly powerful and flexible, allowing you to write complex SQL rules that fit your unique business needs. RLS can be combined with [Supabase Auth](/docs/guides/auth) for end-to-end user security from the browser to the database. RLS is a Postgres primitive and can provide "[defense in depth](https://en.wikipedia.org/wiki/Defense_in_depth_\(computing\))" to protect your data from malicious actors even when accessed through third-party tooling. ## Policies [Policies](https://www.postgresql.org/docs/current/sql-createpolicy.html) are Postgres's rule engine. Policies are easy to understand once you get the hang of them. Each policy is attached to a table, and the policy is executed every time a table is accessed. You can just think of them as adding a `WHERE` clause to every query. For example a policy like this ... ```sql create policy "Individuals can view their own todos." on todos for select using ( (select auth.uid()) = user_id ); ``` .. would translate to this whenever a user tries to select from the todos table: ```sql select * from todos where auth.uid() = todos.user_id; -- Policy is implicitly added. ``` ## Enabling Row Level Security You can enable RLS for any table using the `enable row level security` clause: ```sql alter table "table_name" enable row level security; ``` Once you have enabled RLS, no data will be accessible via the [API](/docs/guides/api) when using the public `anon` key, until you create policies. ## Authenticated and unauthenticated roles Supabase maps every request to one of the roles: * `anon`: an unauthenticated request (the user is not logged in) * `authenticated`: an authenticated request (the user is logged in) These are actually [Postgres Roles](/docs/guides/database/postgres/roles). You can use these roles within your Policies using the `TO` clause: ```sql create policy "Profiles are viewable by everyone" on profiles for select to authenticated, anon using ( true ); -- OR create policy "Public profiles are viewable only by authenticated users" on profiles for select to authenticated using ( true ); ``` ## Creating policies Policies are SQL logic that you attach to a Postgres table. You can attach as many policies as you want to each table. Supabase provides some [helpers](#helper-functions) that simplify RLS if you're using Supabase Auth. We'll use these helpers to illustrate some basic policies: ### SELECT policies You can specify select policies with the `using` clause. Let's say you have a table called `profiles` in the public schema and you want to enable read access to everyone. ```sql -- 1. Create table create table profiles ( id uuid primary key, user_id references auth.users, avatar_url text ); -- 2. Enable RLS alter table profiles enable row level security; -- 3. Create Policy create policy "Public profiles are visible to everyone." on profiles for select to anon -- the Postgres Role (recommended) using ( true ); -- the actual Policy ``` Alternatively, if you only wanted users to be able to see their own profiles: ```sql create policy "User can see their own profile only." on profiles for select using ( (select auth.uid()) = user_id ); ``` ### INSERT policies You can specify insert policies with the `with check` clause. The `with check` expression ensures that any new row data adheres to the policy constraints. Let's say you have a table called `profiles` in the public schema and you only want users to be able to create a profile for themselves. In that case, we want to check their User ID matches the value that they are trying to insert: ```sql -- 1. Create table create table profiles ( id uuid primary key, user_id uuid references auth.users, avatar_url text ); -- 2. Enable RLS alter table profiles enable row level security; -- 3. Create Policy create policy "Users can create a profile." on profiles for insert to authenticated -- the Postgres Role (recommended) with check ( (select auth.uid()) = user_id ); -- the actual Policy ``` ### UPDATE policies You can specify update policies by combining both the `using` and `with check` expressions. The `using` clause represents the condition that must be true for the update to be allowed, and `with check` clause ensures that the updates made adhere to the policy constraints. Let's say you have a table called `profiles` in the public schema and you only want users to be able to update their own profile. You can create a policy where the `using` clause checks if the user owns the profile being updated. And the `with check` clause ensures that, in the resultant row, users do not change the `user_id` to a value that is not equal to their User ID, maintaining that the modified profile still meets the ownership condition. ```sql -- 1. Create table create table profiles ( id uuid primary key, user_id uuid references auth.users, avatar_url text ); -- 2. Enable RLS alter table profiles enable row level security; -- 3. Create Policy create policy "Users can update their own profile." on profiles for update to authenticated -- the Postgres Role (recommended) using ( (select auth.uid()) = user_id ) -- checks if the existing row complies with the policy expression with check ( (select auth.uid()) = user_id ); -- checks if the new row complies with the policy expression ``` If no `with check` expression is defined, then the `using` expression will be used both to determine which rows are visible (normal USING case) and which new rows will be allowed to be added (WITH CHECK case). ### DELETE policies You can specify delete policies with the `using` clause. Let's say you have a table called `profiles` in the public schema and you only want users to be able to delete their own profile: ```sql -- 1. Create table create table profiles ( id uuid primary key, user_id uuid references auth.users, avatar_url text ); -- 2. Enable RLS alter table profiles enable row level security; -- 3. Create Policy create policy "Users can delete a profile." on profiles for delete to authenticated -- the Postgres Role (recommended) using ( (select auth.uid()) = user_id ); -- the actual Policy ``` ### Views Views bypass RLS by default because they are usually created with the `postgres` user. This is a feature of Postgres, which automatically creates views with `security definer`. In Postgres 15 and above, you can make a view obey the RLS policies of the underlying tables when invoked by `anon` and `authenticated` roles by setting `security_invoker = true`. ```sql create view with(security_invoker = true) as select ``` In older versions of Postgres, protect your views by revoking access from the `anon` and `authenticated` roles, or by putting them in an unexposed schema. ## Helper functions Supabase provides some helper functions that make it easier to write Policies. ### `auth.uid()` Returns the ID of the user making the request. ### `auth.jwt()` Returns the JWT of the user making the request. Anything that you store in the user's `raw_app_meta_data` column or the `raw_user_meta_data` column will be accessible using this function. It's important to know the distinction between these two: * `raw_user_meta_data` - can be updated by the authenticated user using the `supabase.auth.update()` function. It is not a good place to store authorization data. * `raw_app_meta_data` - cannot be updated by the user, so it's a good place to store authorization data. The `auth.jwt()` function is extremely versatile. For example, if you store some team data inside `app_metadata`, you can use it to determine whether a particular user belongs to a team. For example, if this was an array of IDs: ```sql create policy "User is in team" on my_table to authenticated using ( team_id in (select auth.jwt() -> 'app_metadata' -> 'teams')); ``` ### MFA The `auth.jwt()` function can be used to check for [Multi-Factor Authentication](/docs/guides/auth/auth-mfa#enforce-rules-for-mfa-logins). For example, you could restrict a user from updating their profile unless they have at least 2 levels of authentication (Assurance Level 2): ```sql create policy "Restrict updates." on profiles as restrictive for update to authenticated using ( (select auth.jwt()->>'aal') = 'aal2' ); ``` ## Bypassing Row Level Security Supabase provides special "Service" keys, which can be used to bypass RLS. These should never be used in the browser or exposed to customers, but they are useful for administrative tasks. You can also create new [Postgres Roles](/docs/guides/database/postgres/roles) which can bypass Row Level Security using the "bypass RLS" privilege: ```sql alter role "role_name" with bypassrls; ``` This can be useful for system-level access. You should *never* share login credentials for any Postgres Role with this privilege. ## RLS performance recommendations Every authorization system has an impact on performance. While row level security is powerful, the performance impact is important to keep in mind. This is especially true for queries that scan every row in a table - like many `select` operations, including those using limit, offset, and ordering. Based on a series of [tests](https://github.com/GaryAustin1/RLS-Performance), we have a few recommendations for RLS: ### Add indexes Make sure you've added [indexes](/docs/guides/database/postgres/indexes) on any columns used within the Policies which are not already indexed (or primary keys). For a Policy like this: ```sql create policy "rls_test_select" on test_table to authenticated using ( (select auth.uid()) = user_id ); ``` You can add an index like: ```sql create index userid on test_table using btree (user_id); ``` #### Benchmarks | Test | Before (ms) | After (ms) | % Improvement | Change | | --------------------------------------------------------------------------------------------- | ----------- | ---------- | ------------- | -------------------------------------------------------------------------------------------------------- | | [test1-indexed](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test1-indexed) | 171 | < 0.1 | 99.94% | | ### Call functions with `select` You can use `select` statement to improve policies that use functions. For example, instead of this: ```sql create policy "rls_test_select" on test_table to authenticated using ( auth.uid() = user_id ); ``` You can do: ```sql create policy "rls_test_select" on test_table to authenticated using ( (select auth.uid()) = user_id ); ``` This method works well for JWT functions like `auth.uid()` and `auth.jwt()` as well as `security definer` Functions. Wrapping the function causes an `initPlan` to be run by the Postgres optimizer, which allows it to "cache" the results per-statement, rather than calling the function on each row. #### Benchmarks | Test | Before (ms) | After (ms) | % Improvement | Change | | --------------------------------------------------------------------------------------------------------------------------------- | ----------- | ---------- | ------------- | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | [test2a-wrappedSQL-uid](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test2a-wrappedSQL-uid\(\)) | 179 | 9 | 94.97% | | | [test2b-wrappedSQL-isadmin](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test2b-wrappedSQL-isadmin\(\)) | 11,000 | 7 | 99.94% | | | [test2c-wrappedSQL-two-functions](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test2c-wrappedSQL-two-functions) | 11,000 | 10 | 99.91% | | | [test2d-wrappedSQL-sd-fun](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test2d-wrappedSQL-sd-fun) | 178,000 | 12 | 99.993% | | | [test2e-wrappedSQL-sd-fun-array](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test2e-wrappedSQL-sd-fun-array) | 173000 | 16 | 99.991% | | ### Add filters to every query Policies are "implicit where clauses," so it's common to run `select` statements without any filters. This is a bad pattern for performance. Instead of doing this (JS client example): ```js const { data } = supabase .from('table') .select() ``` You should always add a filter: ```js const { data } = supabase .from('table') .select() .eq('user_id', userId) ``` Even though this duplicates the contents of the Policy, Postgres can use the filter to construct a better query plan. #### Benchmarks | Test | Before (ms) | After (ms) | % Improvement | Change | | ------------------------------------------------------------------------------------------------- | ----------- | ---------- | ------------- | -------------------------------------------------------------------------------------------------------------------------------------- | | [test3-addfilter](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test3-addfilter) | 171 | 9 | 94.74% | | ### Use security definer functions A "security definer" function runs using the same role that *created* the function. This means that if you create a role with a superuser (like `postgres`), then that function will have `bypassrls` privileges. For example, if you had a policy like this: ```sql create policy "rls_test_select" on test_table to authenticated using ( exists ( select 1 from roles_table where (select auth.uid()) = user_id and role = 'good_role' ) ); ``` We can instead create a `security definer` function which can scan `roles_table` without any RLS penalties: ```sql create function private.has_good_role() returns boolean language plpgsql security definer -- will run as the creator as $$ begin return exists ( select 1 from roles_table where (select auth.uid()) = user_id and role = 'good_role' ); end; $$; -- Update our policy to use this function: create policy "rls_test_select" on test_table to authenticated using ( private.has_good_role() ); ``` ### Minimize joins You can often rewrite your Policies to avoid joins between the source and the target table. Instead, try to organize your policy to fetch all the relevant data from the target table into an array or set, then you can use an `IN` or `ANY` operation in your filter. For example, this is an example of a slow policy which joins the source `test_table` to the target `team_user`: ```sql create policy "rls_test_select" on test_table to authenticated using ( (select auth.uid()) in ( select user_id from team_user where team_user.team_id = team_id -- joins to the source "test_table.team_id" ) ); ``` We can rewrite this to avoid this join, and instead select the filter criteria into a set: ```sql create policy "rls_test_select" on test_table to authenticated using ( team_id in ( select team_id from team_user where user_id = (select auth.uid()) -- no join ) ); ``` In this case you can also consider [using a `security definer` function](#use-security-definer-functions) to bypass RLS on the join table: #### Benchmarks | Test | Before (ms) | After (ms) | % Improvement | Change | | --------------------------------------------------------------------------------------------------- | ----------- | ---------- | ------------- | ------------------------------------------------------------------------------------------------------------------------------------------------- | | [test5-fixed-join](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test5-fixed-join) | 9,000 | 20 | 99.78% | | ### Specify roles in your policies Always use the Role of inside your policies, specified by the `TO` operator. For example, instead of this query: ```sql create policy "rls_test_select" on rls_test using ( auth.uid() = user_id ); ``` Use: ```sql create policy "rls_test_select" on rls_test to authenticated using ( (select auth.uid()) = user_id ); ``` This prevents the policy `( (select auth.uid()) = user_id )` from running for any `anon` users, since the execution stops at the `to authenticated` step. #### Benchmarks | Test | Before (ms) | After (ms) | % Improvement | Change | | --------------------------------------------------------------------------------------------- | ----------- | ---------- | ------------- | -------------------------------------------------------------------------------------------------------------------------------- | | [test6-To-role](https://github.com/GaryAustin1/RLS-Performance/tree/main/tests/test6-To-role) | 170 | < 0.1 | 99.78% | | ## More resources * [Testing your database](/docs/guides/database/testing) * [Row Level Security and Supabase Auth](/docs/guides/database/postgres/row-level-security) * [RLS Guide and Best Practices](https://github.com/orgs/supabase/discussions/14576) * Community repo on testing RLS using [pgTAP and dbdev](https://github.com/usebasejump/supabase-test-helpers/tree/main) # Replicate to another Postgres database using Logical Replication For this example, you will need: * A Supabase project * A Postgres database (running v10 or newer) You will be running commands on both of these databases to publish changes from the Supabase database to the external database. 1. Create a `publication` on the **Supabase database**: ```sql CREATE PUBLICATION example_pub; ``` 2. Also on the **Supabase database**, create a `replication slot`: ```sql select pg_create_logical_replication_slot('example_slot', 'pgoutput'); ``` 3. Now we will connect to our **external database** and subscribe to our `publication` Note: ): ```sql CREATE SUBSCRIPTION example_sub CONNECTION 'host=db.oaguxblfdassqxvvwtfe.supabase.co user=postgres password=YOUR_PASS dbname=postgres' PUBLICATION example_pub WITH (copy_data = true, create_slot=false, slot_name=example_slot); ``` 4. Add all the tables that you want replicated to the publication. ```sql ALTER PUBLICATION example_pub ADD TABLE example_table; ``` 5. Check the replication status using `pg_stat_replication` ```sql select * from pg_stat_replication; ``` # Timeouts Extend database timeouts to execute longer transactions ## Change Postgres timeout You can change the Postgres timeout at the: 1. [Session level](#session-level) 2. [Function level](#function-level) 3. [Global level](#global-level) 4. [Role level](#role-level) ### Session level Session level settings persist only for the duration of the connection. Set the session timeout by running: ```sql set statement_timeout = '10min'; ``` Because it applies to sessions only, it can only be used with connections through Supavisor in session mode (port 5432) or a direct connection. It cannot be used in the Dashboard, with the Supabase Client API, nor with Supavisor in Transaction mode (port 6543). This is most often used for single, long running, administrative tasks, such as creating an HSNW index. Once the setting is implemented, you can view it by executing: ```sql SHOW statement_timeout; ``` See the full guide on [changing session timeouts](https://github.com/orgs/supabase/discussions/21133). ### Function level This works with the Database REST API when called from the Supabase client libraries: ```sql create or replace function myfunc() returns void as $$ select pg_sleep(3); -- simulating some long-running process $$ language sql set statement_timeout TO '4s'; -- set custom timeout ``` This is mostly for recurring functions that need a special exemption for runtimes. ### Role level This sets the timeout for a specific role. The default role timeouts are: * `anon`: 3s * `authenticated`: 8s * `service_role`: none (defaults to the `authenticator` role's 8s timeout if unset) * `postgres`: none (capped by default global timeout to be 2min) Run the following query to change a role's timeout: ```sql alter role example_role set statement_timeout = '10min'; -- could also use seconds '10s' ``` Unlike global settings, the result cannot be checked with `SHOW statement_timeout`. Instead, run: ```sql select rolname, rolconfig from pg_roles where rolname in ( 'anon', 'authenticated', 'postgres', 'service_role' -- , ); ``` ### Global level This changes the statement timeout for all roles and sessions without an explicit timeout already set. ```sql alter database postgres set statement_timeout TO '4s'; ``` Check if your changes took effect: ```sql show statement_timeout; ``` Although not necessary, if you are uncertain if a timeout has been applied, you can run a quick test: ```sql create or replace function myfunc() returns void as $$ select pg_sleep(601); -- simulating some long-running process $$ language sql; ``` ## Identifying timeouts The Supabase Dashboard contains tools to help you identify timed-out and long-running queries. ### Using the Logs Explorer Go to the [Logs Explorer](/dashboard/project/_/logs/explorer), and run the following query to identify timed-out events (`statement timeout`) and queries that successfully run for longer than 10 seconds (`duration`). ```sql select cast(postgres_logs.timestamp as datetime) as timestamp, event_message, parsed.error_severity, parsed.user_name, parsed.query, parsed.detail, parsed.hint, parsed.sql_state_code, parsed.backend_type from postgres_logs cross join unnest(metadata) as metadata cross join unnest(metadata.parsed) as parsed where regexp_contains(event_message, 'duration|statement timeout') -- (OPTIONAL) MODIFY OR REMOVE and parsed.user_name = 'authenticator' -- <--------CHANGE order by timestamp desc limit 100; ``` ### Using the Query Performance page Go to the [Query Performance page](/dashboard/project/_/advisors/query-performance?preset=slowest_execution) and filter by relevant role and query speeds. This only identifies slow-running but successful queries. Unlike the Log Explorer, it does not show you timed-out queries. ### Understanding roles in logs Each API server uses a designated user for connecting to the database: | Role | API/Tool | | ---------------------------- | ------------------------------------------------------------------------- | | `supabase_admin` | Used by Realtime and for project configuration | | `authenticator` | PostgREST | | `supabase_auth_admin` | Auth | | `supabase_storage_admin` | Storage | | `supabase_replication_admin` | Synchronizes Read Replicas | | `postgres` | Supabase Dashboard and External Tools (e.g., Prisma, SQLAlchemy, PSQL...) | | Custom roles | External Tools (e.g., Prisma, SQLAlchemy, PSQL...) | Filter by the `parsed.user_name` field to only retrieve logs made by specific users: ```sql -- find events based on role/server ... query where -- find events from the relevant role parsed.user_name = '' ``` # Postgres Triggers Automatically execute SQL on table events. In Postgres, a trigger executes a set of actions automatically on table events such as INSERTs, UPDATEs, DELETEs, or TRUNCATE operations. ## Creating a trigger Creating triggers involve 2 parts: 1. A [Function](/docs/guides/database/functions) which will be executed (called the Trigger Function) 2. The actual Trigger object, with parameters around when the trigger should be run. An example of a trigger is: ```sql create trigger "trigger_name" after insert on "table_name" for each row execute function trigger_function(); ``` ## Trigger functions A trigger function is a user-defined [Function](/docs/guides/database/functions) that Postgres executes when the trigger is fired. ### Example trigger function Here is an example that updates `salary_log` whenever an employee's salary is updated: ```sql -- Example: Update salary_log when salary is updated create function update_salary_log() returns trigger language plpgsql as $$ begin insert into salary_log(employee_id, old_salary, new_salary) values (new.id, old.salary, new.salary); return new; end; $$; create trigger salary_update_trigger after update on employees for each row execute function update_salary_log(); ``` ### Trigger variables Trigger functions have access to several special variables that provide information about the context of the trigger event and the data being modified. In the example above you can see the values inserted into the salary log are `old.salary` and `new.salary` - in this case `old` specifies the previous values and `new` specifies the updated values. Here are some of the key variables and options available within trigger functions: * `TG_NAME`: The name of the trigger being fired. * `TG_WHEN`: The timing of the trigger event (`BEFORE` or `AFTER`). * `TG_OP`: The operation that triggered the event (`INSERT`, `UPDATE`, `DELETE`, or `TRUNCATE`). * `OLD`: A record variable holding the old row's data in `UPDATE` and `DELETE` triggers. * `NEW`: A record variable holding the new row's data in `UPDATE` and `INSERT` triggers. * `TG_LEVEL`: The trigger level (`ROW` or `STATEMENT`), indicating whether the trigger is row-level or statement-level. * `TG_RELID`: The object ID of the table on which the trigger is being fired. * `TG_TABLE_NAME`: The name of the table on which the trigger is being fired. * `TG_TABLE_SCHEMA`: The schema of the table on which the trigger is being fired. * `TG_ARGV`: An array of string arguments provided when creating the trigger. * `TG_NARGS`: The number of arguments in the `TG_ARGV` array. ## Types of triggers There are two types of trigger, `BEFORE` and `AFTER`: ### Trigger before changes are made Executes before the triggering event. ```sql create trigger before_insert_trigger before insert on orders for each row execute function before_insert_function(); ``` ### Trigger after changes are made Executes after the triggering event. ```sql create trigger after_delete_trigger after delete on customers for each row execute function after_delete_function(); ``` ## Execution frequency There are two options available for executing triggers: * `for each row`: specifies that the trigger function should be executed once for each affected row. * `for each statement`: the trigger is executed once for the entire operation (for example, once on insert). This can be more efficient than `for each row` when dealing with multiple rows affected by a single SQL statement, as they allow you to perform calculations or updates on groups of rows at once. ## Dropping a trigger You can delete a trigger using the `drop trigger` command: ```sql drop trigger "trigger_name" on "table_name"; ``` ## Resources * Official Postgres Docs: [Triggers](https://www.postgresql.org/docs/current/triggers.html) * Official Postgres Docs: [Overview of Trigger Behavior](https://www.postgresql.org/docs/current/trigger-definition.html) * Official Postgres Docs: [CREATE TRIGGER](https://www.postgresql.org/docs/current/sql-createtrigger.html) # Print PostgreSQL version It's important to know which version of Postgres you are running as each major version has different features and may cause breaking changes. You may also need to update your schema when [upgrading](https://www.postgresql.org/docs/current/pgupgrade.html) or downgrading to a major Postgres version. Run the following query using the [SQL Editor](https://supabase.com/dashboard/project/_/sql) in the Supabase Dashboard: ```sql select version(); ``` Which should return something like: ```sql PostgreSQL 15.1 on aarch64-unknown-linux-gnu, compiled by gcc (Ubuntu 10.3.0-1ubuntu1~20.04) 10.3.0, 64-bit ``` This query can also be executed via `psql` or any other query editor if you prefer to [connect directly to the database](/docs/guides/database/connecting-to-postgres#direct-connections). # Prisma 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/prisma-troubleshooting). # Troubleshooting prisma errors This guide addresses common Prisma errors that you might encounter while using Supabase. ## 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 `num_cpus * 2 + 1` 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`. # Connecting with PSQL [`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: ![Connection Info and Certificate.](/docs/img/database/database-settings-ssl.png) 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]" ``` # Query Optimization Choosing indexes to improve your query performance. When working with Postgres, or any relational database, indexing is key to improving query performance. Aligning indexes with common query patterns can speed up data retrieval by an order of magnitude. This guide is intended to: * help identify parts of a query that have the potential to be improved by indexes * introduce tooling to help identify useful indexes This is not a comprehensive resource, but rather a helpful starting point for your optimization journey. If you're new to query optimization, you may be interested in [`index_advisor`](/docs/guides/database/extensions/index_advisor), our tool for automatically detecting indexes that improve performance on a given query. ## Example query Consider the following example query that retrieves customer names and purchase dates from two tables: ```sql select a.name, b.date_of_purchase from customers as a join orders as b on a.id = b.customer_id where a.sign_up_date > '2023-01-01' and b.status = 'shipped' order by b.date_of_purchase limit 10; ``` In this query, there are several parts that indexes could likely help in optimizing the performance: ### `where` clause: The `where` clause filters rows based on certain conditions, and indexing the columns involved can improve this process: * `a.sign_up_date`: If filtering by `sign_up_date` is common, indexing this column can speed up the query. * `b.status`: Indexing the status may be beneficial if the column has diverse values. ```sql create index idx_customers_sign_up_date on customers (sign_up_date); create index idx_orders_status on orders (status); ``` ### `join` columns Indexes on the columns used for joining tables can help Postgres avoid scanning tables in their entirety when connecting tables. * Indexing `a.id` and `b.customer_id` would likely improve the performance of the join in this query. * Note that if `a.id` is the primary key of the `customers` table it is already indexed ```sql create index idx_orders_customer_id on orders (customer_id); ``` ### `order by` clause Sorting can also be optimized by indexing: * An index on `b.date_of_purchase` can improve the sorting process, and is particularly beneficial when a subset of rows is being returned with a `limit` clause. ```sql create index idx_orders_date_of_purchase on orders (date_of_purchase); ``` ## Key concepts Here are some concepts and tools to keep in mind to help you identify the best index for the job, and measure the impact that your index had: ### Analyze the query plan Use the `explain` command to understand the query's execution. Look for slow parts, such as Sequential Scans or high cost numbers. If creating an index does not reduce the cost of the query plan, remove it. For example: ```sql explain select * from customers where sign_up_date > 25; ``` ### Use appropriate index types Postgres offers various index types like [B-tree, Hash, GIN, etc](https://www.postgresql.org/docs/current/indexes-types.html). Select the type that best suits your data and query pattern. Using the right index type can make a significant difference. For example, using a BRIN index on a field that always increases and lives within a table that updates infrequently - like `created_at` on an `orders` table - routinely results in indexes that are +10x smaller than the equivalent default B-tree index. That translates into better scalability. ```sql create index idx_orders_created_at ON customers using brin(created_at); ``` ### Partial indexes For queries that frequently target a subset of data, a partial index could be faster and smaller than indexing the entire column. A partial index contains a `where` clause to filter the values included in the index. Note that a query's `where` clause must match the index for it to be used. ```sql create index idx_orders_status on orders (status) where status = 'shipped'; ``` ### Composite indexes If filtering or joining on multiple columns, a composite index prevents Postgres from referring to multiple indexes when identifying the relevant rows. ```sql create index idx_customers_sign_up_date_priority on customers (sign_up_date, priority); ``` ### Over-Indexing Avoid the urge to index columns you operate on infrequently. While indexes can speed up reads, they also slow down writes, so it's important to balance those factors when making indexing decisions. ### Statistics Postgres maintains a set of statistics about the contents of your tables. Those statistics are used by the query planner to decide when it's is more efficient to use an index vs scanning the entire table. If the collected statistics drift too far from reality, the query planner may make poor decisions. To avoid this risk, you can periodically `analyze` tables. ```sql analyze customers; ``` *** By following this guide, you'll be able to discern where indexes can optimize queries and enhance your Postgres performance. Remember that each database is unique, so always consider the specific context and use case of your queries. # Replication Replication is a technique for copying the data from one database to another. Supabase uses replication functionality to provide a real-time API. Replication is useful for: * Spreading out the "load." For example, if your database has a lot of reads, you might want to split it between two databases. * Reducing latency. For example, you may want one database in London to serve your European customers, and one in New York to serve the US. Replication is done through *publications*, a method of choosing which changes to send to other systems (usually another Postgres database). Publications can be managed in the [Dashboard](https://supabase.com/dashboard) or with SQL. ## Manage publications in the dashboard 1. Go to the [Database](https://supabase.com/dashboard/project/_/database/tables) page in the Dashboard. 2. Click on **Publications** in the sidebar. 3. Control which database events are sent by toggling **Insert**, **Update**, and **Delete**. 4. Control which tables broadcast changes by selecting **Source** and toggling each table. ## Create a publication This publication contains changes to all tables. ```sql create publication publication_name for all tables; ``` ## Create a publication to listen to individual tables ```sql create publication publication_name for table table_one, table_two; ``` ## Add tables to an existing publication ```sql alter publication publication_name add table table_name; ``` ## Listen to `insert` ```sql create publication publication_name for all tables with (publish = 'insert'); ``` ## Listen to `update` ```sql create publication publication_name for all tables with (publish = 'update'); ``` ## Listen to `delete` ```sql create publication publication_name for all tables with (publish = 'delete'); ``` ## Remove a publication ```sql drop publication if exists publication_name; ``` ## Recreate a publication If you're recreating a publication, it's best to do it in a transaction to ensure the operation succeeds. ```sql begin; -- remove the realtime publication drop publication if exists publication_name; -- re-create the publication but don't enable it for any tables create publication publication_name; commit; ``` # Securing your data Supabase helps you control access to your data. With access policies, you can protect sensitive data and make sure users only access what they're allowed to see. ## Connecting your app securely Supabase allows you to access your database using the auto-generated [Data APIs](/docs/guides/database/connecting-to-postgres#data-apis). This speeds up the process of building web apps, since you don't need to write your own backend services to pass database queries and results back and forth. You can keep your data secure while accessing the Data APIs from the frontend, so long as you: * Turn on [Row Level Security](/docs/guides/database/postgres/row-level-security) (RLS) for your tables * Use your Supabase **anon key** when you create a Supabase client Your anon key is safe to expose with RLS enabled, because row access permission is checked against your access policies and the user's [JSON Web Token (JWT)](/docs/learn/auth-deep-dive/auth-deep-dive-jwts). The JWT is automatically sent by the Supabase client libraries if the user is logged in using Supabase Auth. ## More information Supabase and Postgres provide you with multiple ways to manage security, including but not limited to Row Level Security. See the Access and Security pages for more information: * [Row Level Security](/docs/guides/database/postgres/row-level-security) * [Column Level Security](/docs/guides/database/postgres/column-level-security) * [Hardening the Data API](/docs/guides/database/hardening-data-api) * [Managing Postgres roles](/docs/guides/database/postgres/roles) * [Managing secrets with Vault](/docs/guides/database/vault) # Supavisor 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 | | Error: received invalid response to GSSAPI negotiation: S | This error happens due to `gssencmode` parameter not set to disabled. | Follow this [guide](https://github.com/orgs/supabase/discussions/30173) to resolve. | # 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: | `id` | `name` | `description` | | ---- | -------------------- | ------------------------------------------------------------------------------------------------------------------------------------------------------------- | | 1 | The Phantom Menace | Two Jedi escape a hostile blockade to find allies and come across a young boy who may bring balance to the Force. | | 2 | Attack of the Clones | Ten years after the invasion of Naboo, the Galactic Republic is facing a Separatist movement. | | 3 | Revenge of the Sith | As 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. | | 4 | Star Wars | Luke 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. 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](../../guides/database/connecting-to-postgres) to your database and run the SQL queries yourself. ## Columns You must define the "data type" when you create a column. ### Data types Every column is a predefined type. Postgres provides many [default types](https://www.postgresql.org/docs/current/datatype.html), 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. 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. ```sql create table movies ( id bigint generated always as identity primary key ); ``` 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. ```sql create table movies ( id bigint generated by default as identity primary key ); ``` ## Loading data There are several ways to load data in Supabase. You can load data directly into the database or using the [APIs](../../guides/database/api). Use the "Bulk Loading" instructions if you are loading large data sets. ### Basic data loading ### Bulk data loading When inserting large data sets it's best to use PostgreSQL's [COPY](https://www.postgresql.org/docs/current/sql-copy.html) 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: ```text ./movies.csv "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." "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](../../guides/database/connecting-to-postgres#direct-connections) to your database directly and load the file with the COPY command: ```bash psql -h DATABASE_URL -p 5432 -d postgres -U postgres \ -c "\COPY movies FROM './movies.csv';" ``` Additionally use the `DELIMITER`, `HEADER` and `FORMAT` options as defined in the Postgres [COPY](https://www.postgresql.org/docs/current/sql-copy.html) docs. ```bash psql -h DATABASE_URL -p 5432 -d postgres -U postgres \ -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. 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. ```sql create table categories ( id bigint generated always as identity primary key, name text -- category name ); alter table movies 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. 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: ```sql create schema private; ``` Now we can create tables inside the `private` schema: ```sql create table private.salaries ( id bigint generated by default as identity primary key, salary bigint not null, actor_id bigint not null references public.actors ); ``` ## 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`** | id | name | type | | --- | ---------------- | ------------- | | 1 | Princess Leia | undergraduate | | 2 | Yoda | graduate | | 3 | Anakin Skywalker | graduate | **`courses`** | id | title | code | | --- | ------------------------ | ------- | | 1 | Introduction to Postgres | PG101 | | 2 | Authentication Theories | AUTH205 | | 3 | Fundamentals of Supabase | SUP412 | **`grades`** | id | student\_id | course\_id | result | | --- | ---------- | --------- | ------ | | 1 | 1 | 1 | B+ | | 2 | 1 | 3 | A+ | | 3 | 2 | 2 | A | | 4 | 3 | 1 | A- | | 5 | 3 | 2 | A | | 6 | 3 | 3 | B- | Creating a view consisting of all the three tables will look like this: ```sql create view transcripts as select students.name, students.type, courses.title, courses.code, grades.result from grades left join students on grades.student_id = students.id left join courses on grades.course_id = courses.id; grant all on table transcripts to authenticated; ``` Once done, we can now access the underlying query with: ```sql select * from transcripts; ``` ### View security By default, views are accessed with their creator's permission ("security definer"). If a privileged role creates a view, others accessing it will use that role's elevated permissions. To enforce row level security policies, define the view with the "security invoker" modifier. ```sql -- alter a security_definer view to be security_invoker alter view set (security_invoker = true); -- create a view with the security_invoker modifier create view with(security_invoker=true) as ( select * from ); ``` ### 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: ```sql select students.name, students.type, courses.title, courses.code, grades.result from grades left join students on grades.student_id = students.id left join courses on grades.course_id = courses.id; ``` We can run this instead: ```sql select * from transcripts; ``` Additionally, a view behaves like a typical table. We can safely use it in table `JOIN`s 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: ```sql select students.name, students.type, courses.title, courses.code, grades.result from grades left join students on grades.student_id = students.id left join courses on grades.course_id = courses.id 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 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](https://www.postgresql.org/docs/12/rules-materializedviews.html) 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: ```sql create materialized view transcripts as select students.name, students.type, courses.title, courses.code, grades.result from grades left join students on grades.student_id = students.id left join courses on grades.course_id = courses.id; ``` Reading from the materialized view is the same as a conventional view: ```sql 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: ```sql 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 * [Official Docs: Create table](https://www.postgresql.org/docs/current/sql-createtable.html) * [Official Docs: Create view](https://www.postgresql.org/docs/12/sql-createview.html) * [Postgres Tutorial: Create tables](https://www.postgresqltutorial.com/postgresql-tutorial/postgresql-create-table/) * [Postgres Tutorial: Add column](https://www.postgresqltutorial.com/postgresql-tutorial/postgresql-add-column/) * [Postgres Tutorial: Views](https://www.postgresqltutorial.com/postgresql-views/) # Testing Your Database To ensure that queries return the expected data, RLS policies are correctly applied and etc., we encourage you to write automated tests. There are essentially two approaches to testing: * Firstly, you can write tests that interface with a Supabase client instance (same way you use Supabase client in your application code) in the programming language(s) you use in your application and using your favorite testing framework. * Secondly, you can test through the Supabase CLI, which is a more low-level approach where you write tests in SQL. # Testing using the Supabase CLI You can use the Supabase CLI to test your database. The minimum required version of the CLI is [v1.11.4](https://github.com/supabase/cli/releases). To get started: * [Install the Supabase CLI](/docs/guides/cli) on your local machine ## Creating a test Create a tests folder inside the `supabase` folder: ```bash mkdir -p ./supabase/tests/database ``` Create a new file with the `.sql` extension which will contain the test. ```bash touch ./supabase/tests/database/hello_world.test.sql ``` ## Writing tests All `sql` files use [pgTAP](/docs/guides/database/extensions/pgtap) as the test runner. Let's write a simple test to check that our `auth.users` table has an ID column. Open `hello_world.test.sql` and add the following code: ```sql begin; select plan(1); -- only one statement to run SELECT has_column( 'auth', 'users', 'id', 'id should exist' ); select * from finish(); rollback; ``` ## Running tests To run the test, you can use: ```bash supabase test db ``` This will produce the following output: ```bash $ supabase test db supabase/tests/database/hello_world.test.sql .. ok All tests successful. Files=1, Tests=1, 1 wallclock secs ( 0.01 usr 0.00 sys + 0.04 cusr 0.02 csys = 0.07 CPU) Result: PASS ``` ## More resources * [Testing RLS policies](/docs/guides/database/extensions/pgtap#testing-rls-policies) * [pgTAP extension](/docs/guides/database/extensions/pgtap) * Official [pgTAP documentation](https://pgtap.org/) # Vault Managing secrets in Postgres. Vault is a Postgres extension and accompanying Supabase UI that makes it safe and easy to store encrypted secrets and other data in your database. This opens up a lot of possibilities to use Postgres in ways that go beyond what is available in a stock distribution. Under the hood, the Vault is a table of Secrets and Encryption Keys that are stored using [Authenticated Encryption](https://en.wikipedia.org/wiki/Authenticated_encryption) on disk. They are then available in decrypted form through a Postgres view so that the secrets can be used by applications from SQL. Because the secrets are stored on disk encrypted and authenticated, any backups or replication streams also preserve this encryption in a way that can't be decrypted or forged. Supabase provides a dashboard UI for the Vault that makes storing secrets easy. Click a button, type in your secret, and save. Optionally create your own keys you can use to encrypt your secret. Your secret will then be stored on disk encrypted using the specified key. There are two main parts to the Vault UI, Secrets and Encryption Keys: ## Secrets You can use the Vault to store secrets - everything from Environment Variables to API Keys. You can then use these secrets anywhere in your database: Postgres [Functions](/docs/guides/database/functions), Triggers, and [Webhooks](/docs/guides/database/webhooks). From a SQL perspective, accessing secrets is as easy as querying a table (or in this case, a view). The underlying secrets tables will be stored in encrypted form. ## Encryption keys These are keys used to encrypt data inside your database. You can create different Encryption Keys for different purposes, for example: one for encrypting user-data, and another for application-data. Each key is encrypted itself using a root encryption key that lives outside of the database. See **[Encryption key location](#encryption-key-location)** for more details. ## Using the Vault You can manage secrets and encryption keys from the UI or using SQL. ### Adding secrets There is also a handy function for creating secrets called `vault.create_secret()`: ```sql select vault.create_secret('my_s3kre3t'); ``` The function returns the UUID of the new secret. Secrets can also have an optional *unique* name and an optional description. These are also arguments to `vault.create_secret()`: ```sql select vault.create_secret('another_s3kre3t', 'unique_name', 'This is the description'); ``` Alternatively, you can create a secret by inserting data into the `vault.secret` table: ```sql insert into vault.secrets (secret) values ('s3kre3t_k3y') returning *; ``` ### Viewing secrets If you look in the `vault.secrets` table, you will see that your data is stored encrypted. To decrypt the data, there is an automatically created view `vault.decrypted_secrets`. This view will decrypt secret data on the fly: ```sql select * from vault.decrypted_secrets order by created_at desc limit 3; ``` Notice how this view has a `decrypted_secret` column that contains the decrypted secrets. Views are not stored on disk, they are only run at query time, so the secret remains encrypted on disk, and in any backup dumps or replication streams. You should ensure that you protect access to this view with the appropriate SQL privilege settings at all times, as anyone that has access to the view has access to decrypted secrets. ### Updating secrets A secret can be updated with the `vault.update_secret()` function, this function makes updating secrets easy, just provide the secret UUID as the first argument, and then an updated secret, updated optional unique name, or updated description: ```sql select vault.update_secret( '7095d222-efe5-4cd5-b5c6-5755b451e223', 'n3w_upd@ted_s3kret', 'updated_unique_name', 'This is the updated description' ); ``` ## Deep dive As we mentioned, the Vault uses `pgsodium`'s Transparent Column Encryption (TCE) to store secrets in an authenticated encrypted form. There are some details around that you may be curious about, what does authenticated mean, and where are encryption keys store? This section explains those details. ### Authenticated encryption with associated data The first important feature of TCE is that it uses an [Authenticated Encryption with Associated Data](https://en.wikipedia.org/wiki/Authenticated_encryption#Authenticated_encryption_with_associated_data_\(AEAD\)) encryption algorithm (based on `libsodium`). ### Encryption key location **Authenticated Encryption** means that in addition to the data being encrypted, it is also signed so that it cannot be forged. You can guarantee that the data was encrypted by someone you trust, which you wouldn't get with encryption alone. The decryption function verifies that the signature is valid *before decrypting the value*. **Associated Data** means that you can include any other columns from the same row as part of the signature computation. This doesn't encrypt those other columns - rather it ensures that your encrypted value is only associated with columns from that row. If an attacker were to copy an encrypted value from another row to the current one, the signature would be rejected (assuming you used a unique column in the associated data). Another important feature of `pgsodium` is that the encryption keys are never stored in the database alongside the encrypted data. Instead, only a **Key ID** is stored, which is a reference to the key that is only accessible outside of SQL. Even if an attacker can capture a dump of your entire database, they will see only encrypted data and key IDs, *never the raw key itself*. This is an important safety precaution - there is little value in storing the encryption key in the database itself as this would be like locking your front door but leaving the key in the lock! Storing the key outside the database fixes this issue. Where are the keys stored? Supabase creates and manages the root keys (from which all key IDs are derived) in our secured backend systems. We keep this root key safe and separate from your data. You remain in control of your keys - a separate API endpoint is available that you can use to access the key if you want to decrypt your data outside of Supabase. ### Internal details To encrypt data, you need a *key id*. You can use the default key id created automatically for every project, or create your own key ids Using the `pgsodium.create_key()` function. Key ids are used to internally derive the encryption key used to encrypt secrets in the vault. Vault users typically do not have access to the key itself, only the key id. Both `vault.create_secret()` and `vault.update_secret()` take an optional fourth `new_key_id` argument. This argument can be used to store a different key id for the secret instead of the default value. ```sql select vault.create_secret( 'another_s3kre3t_key', 'another_unique_name', 'This is another description', (pgsodium.create_key()).id ); ``` Result: ```sh -[ RECORD 1 ]-+------------------------------------- create_secret | cec9e005-a44d-4b19-86e1-febf3cd40619 ``` Which roles should have access to the `vault.secrets` table should be carefully considered. There are two ways to grant access, the first is that the `postgres` user can explicitly grant access to the vault table itself. ### Resources * Read more about Supabase Vault in the [blog post](https://supabase.com/blog/vault-now-in-beta) * [Supabase Vault on GitHub](https://github.com/supabase/vault) * [Column Encryption](/docs/guides/database/column-encryption) # Database Webhooks Trigger external payloads on database events. Database Webhooks allow you to send real-time data from your database to another system whenever a table event occurs. You can hook into three table events: `INSERT`, `UPDATE`, and `DELETE`. All events are fired *after* a database row is changed. ## Webhooks vs triggers Database Webhooks are very similar to triggers, and that's because Database Webhooks are just a convenience wrapper around triggers using the [pg\_net](/docs/guides/database/extensions/pgnet) extension. This extension is asynchronous, and therefore will not block your database changes for long-running network requests. This video demonstrates how you can create a new customer in Stripe each time a row is inserted into a `profiles` table: ## Creating a webhook 1. Create a new [Database Webhook](https://supabase.com/dashboard/project/_/integrations/hooks) in the Dashboard. 2. Give your Webhook a name. 3. Select the table you want to hook into. 4. Select one or more events (table inserts, updates, or deletes) you want to hook into. Since webhooks are just database triggers, you can also create one from SQL statement directly. ```sql create trigger "my_webhook" after insert on "public"."my_table" for each row execute function "supabase_functions"."http_request"( 'http://host.docker.internal:3000', 'POST', '{"Content-Type":"application/json"}', '{}', '1000' ); ``` We currently support HTTP webhooks. These can be sent as `POST` or `GET` requests with a JSON payload. ## Payload The payload is automatically generated from the underlying table record: ```typescript type InsertPayload = { type: 'INSERT' table: string schema: string record: TableRecord old_record: null } type UpdatePayload = { type: 'UPDATE' table: string schema: string record: TableRecord old_record: TableRecord } type DeletePayload = { type: 'DELETE' table: string schema: string record: null old_record: TableRecord } ``` ## Monitoring Logging history of webhook calls is available under the `net` schema of your database. For more info, see the [GitHub Repo](https://github.com/supabase/pg_net). ## Local development When using Database Webhooks on your local Supabase instance, you need to be aware that the Postgres database runs inside a Docker container. This means that `localhost` or `127.0.0.1` in your webhook URL will refer to the container itself, not your host machine where your application is running. To target services running on your host machine, use `host.docker.internal`. If that doesn't work, you may need to use your machine's local IP address instead. For example, if you want to trigger an edge function when a webhook fires, your webhook URL would be: http://host.docker.internal:54321/functions/v1/my-function-name If you're experiencing connection issues with webhooks locally, verify you're using the correct hostname instead of `localhost`. ## Resources * [pg\_net](/docs/guides/database/extensions/pgnet): an async networking extension for Postgres # Deployment Deploying your app makes it live and accessible to users. Usually, you will deploy an app to at least two environments: a production environment for users and (one or multiple) staging or preview environments for developers. Supabase provides several options for environment management and deployment. ## Environment management You can maintain separate development, staging, and production environments for Supabase: * **Development**: Develop with a local Supabase stack using the [Supabase CLI](/docs/guides/local-development). * **Staging**: Use [branching](/docs/guides/deployment/branching) to create staging or preview environments. You can use persistent branches for a long-lived staging setup, or ephemeral branches for short-lived previews (which are often tied to a pull request). * **Production**: If you have branching enabled, you can use the Supabase GitHub integration to automatically push your migration files when you merge a pull request. Alternatively, you can set up your own continuous deployment pipeline using the Supabase CLI. ## Deployment You can automate deployments using: * The [Supabase GitHub integration](/dashboard/project/_/settings/integrations) (with branching enabled) * The [Supabase CLI](/docs/guides/local-development) in your own continuous deployment pipeline * The [Supabase Terraform provider](/docs/guides/deployment/terraform) # Branching Use Supabase Branches to test and preview changes Use branching to safely experiment with changes to your Supabase project. Supabase branches work like Git branches. They let you create and test changes like new configurations, database schemas, or features in a separate, temporary instance without affecting your production setup. When you're ready to ship your changes, merge your branch to update your production instance with the new changes. If you understand Git, you already understand Supabase Branching. ## How branching works * **Separate Environments**: Each branch is a separate environment with its own Supabase instance and API credentials. * **Git Integration**: Branching works with Git, currently supporting GitHub repositories. * **Preview Branches**: You can create multiple Preview Branches for testing. * **Migrations and Seeding**: Branches run migrations from your repository and can seed data using a `seed.sql` file. ## Prerequisites * **Supabase Project**: You need an existing Supabase project. * **GitHub Repository**: Your project must be connected to a GitHub repository containing your Supabase directory. You can run multiple Preview Branches for every Supabase project. Branches contain all the Supabase features with their own API credentials. Preview Environments auto-pause after minutes of inactivity. Upon receiving a new request to your database or REST API, the paused branch will automatically resume to serve the request. The implications of this architecture means * `pg_cron` jobs will not execute in an auto-paused database. * Larger variance in request latency due to database cold starts. If you need higher performance guarantees on your Preview Environment, you can switch individual branches to [persistent](/docs/guides/deployment/branching#persistent-branches) so they are not auto-paused. ### Branching workflow Preview Branch instances contain no data by default. You must include a seed file to seed your preview instance with sample data when the Preview Branch is created. Future versions of Branching may allow for automated data seeding and cloning after we are confident that we can provide safe data masking. ## Git providers To manage code changes, your Supabase project must be connected to a Git repository. At this stage, we only support [GitHub](#branching-with-github). If you are interested in other Git providers, join the [discussion](https://github.com/orgs/supabase/discussions/18936) for GitLab, Bitbucket, and non-Git based Branching. ### Branching with GitHub Supabase Branching uses the Supabase GitHub integration to read files from your GitHub repository. With this integration, Supabase watches all commits, branches, and pull requests of your GitHub repository. You can create a corresponding Preview Branch for any Git branch in your repository. Each time a new Preview Branch is created and configured based on the [`config.toml`](/docs/guides/local-development/cli/config) configuration on this branch, the migrations from the corresponding Git branch are run on the Preview Branch. The Preview Branch is also [seeded](/docs/guides/local-development/seeding-your-database) with sample data based on `./supabase/seed.sql` by default, if that file exists. Supabase Branching follows the [Trunk Based Development](https://trunkbaseddevelopment.com/) workflow, with one main Production branch and multiple development branches: When you merge your Git branch into the production branch, all new migrations will be applied to your Production environment. If you have declared Storage buckets or Edge Functions in `config.toml`, they will also be deployed automatically. All other configurations, including API, Auth, and seed files, will be ignored by default. ### Preparing your Git repository You can use the [Supabase CLI](/docs/guides/cli) to manage changes inside a local `./supabase` directory: ### Enable Supabase branching Once your repository is [correctly prepared](#preparing-your-git-repository), you can enable branching from the Supabase dashboard. ### Open a pull request When you open a pull request on GitHub, the Supabase integration automatically checks for a matching preview branch. If one doesn't exist, it gets created. A comment is added to your PR with the deployment status of your preview branch. Statuses are shown separately for Database, Services, and APIs. Every time a new commit is pushed that changes the migration files in `./supabase/migrations`, the new migrations are run against the preview branch. You can check the status of these runs in the comment's Tasks table. ### Preventing migration failures We highly recommend turning on a 'required check' for the Supabase integration. You can do this from your GitHub repository settings. This prevents PRs from being merged when migration checks fail, and stops invalid migrations from being merged into your production branch. ### Manually create a preview branch Preview branches are automatically created for each pull request, but you can also manually create one. The Git integration watches for changes in the `supabase` directory. This includes: * All SQL migration files, under the subdirectory `migrations` * An optional `seed.sql` file, used to seed preview instances with sample data You can create new migrations either [locally](#develop-locally) or [remotely](#develop-remotely). Local development is recommended. ### Disable branching You can disable branching at any time. Navigate to the [Branches](/dashboard/project/_/branches) page, which can be found via the Branches dropdown menu on the top navigation, then click "Manage Branches" in the menu. Click the 'Disable branching' button at the top of the Overview section. ### Persistent branches Persistent branches are the type of branches that will remain active even after the underlying PR is closed. You can change any branch to be persistent on the [Branches](/dashboard/project/_/branches) page by clicking the triple dots icon next to the branch you want to modify, and selecting "Switch to persistent". All persistent branches can be toggled back to be an ephemeral branch in the exact same way. ## Migration and seeding behavior Migrations are run in sequential order. Each migration builds upon the previous one. The preview branch has a record of which migrations have been applied, and only applies new migrations for each commit. This can create an issue when rolling back migrations. ### Using ORM or custom seed scripts If you want to use your own ORM for managing migrations and seed scripts, you will need to run them in GitHub Actions after the preview branch is ready. The branch credentials can be fetched using the following example GHA workflow. ```yaml on: pull_request: types: - opened - reopened - synchronize branches: - main paths: - 'supabase/**' jobs: wait: runs-on: ubuntu-latest outputs: status: ${{ steps.check.outputs.conclusion }} steps: - uses: fountainhead/action-wait-for-check@v1.2.0 id: check with: checkName: Supabase Preview ref: ${{ github.event.pull_request.head.sha }} token: ${{ secrets.GITHUB_TOKEN }} migrate: needs: - wait if: ${{ needs.wait.outputs.status == 'success' }} runs-on: ubuntu-latest steps: - uses: supabase/setup-cli@v1 with: version: latest - run: supabase --experimental branches get "$GITHUB_HEAD_REF" -o env >> $GITHUB_ENV - name: Custom ORM migration run: psql "$POSTGRES_URL_NON_POOLING" -c 'select 1' ``` ## Branch configuration with remotes When Branching is enabled, your `config.toml` settings automatically sync to all ephemeral branches through a one-to-one mapping between your Git and Supabase branches. ### Basic configuration To update configuration for a Supabase branch, modify `config.toml` and push to git. The Supabase integration will detect the changes and apply them to the corresponding branch. ### Remote-specific configuration For persistent branches that need specific settings, you can use the `[remotes]` block in your `config.toml`. Each remote configuration must reference an existing project ID. Here's an example of configuring a separate seed script for a staging environment: ```toml [remotes.staging] project_id = "your-project-ref" [remotes.staging.db.seed] sql_paths = ["./seeds/staging.sql"] ``` Since the `project_id` field must reference an existing branch, you need to create the persistent branch before adding its configuration. Use the CLI to create a persistent branch first: ```bash supabase --experimental branches create --persistent # Do you want to create a branch named develop? [Y/n] ``` ### Configuration merging When merging a PR into a persistent branch, the Supabase integration: 1. Checks for configuration changes 2. Logs the changes 3. Applies them to the target remote If no remote is declared or the project ID is incorrect, the configuration step is skipped. ### Available configuration options All standard configuration options are available in the `[remotes]` block. This includes: * Database settings * API configurations * Authentication settings * Edge Functions configuration * And more You can use this to maintain different configurations for different environments while keeping them all in version control. ### Rolling back migrations You might want to roll back changes you've made in an earlier migration change. For example, you may have pushed a migration file containing schema changes you no longer want. To fix this, push your latest changes, then delete the preview branch in Supabase and reopen it. The new preview branch is reseeded from your `./supabase/seed.sql` file by default. Any additional data changes you made on the old preview branch are lost. This is equivalent to running `supabase db reset` locally. All migrations are rerun in sequential order. ### Seeding behavior Your Preview Branches are seeded with sample data using the same as [local seeding behavior](/docs/guides/local-development/seeding-your-database). The database is only seeded once, when the preview branch is created. To rerun seeding, delete the preview branch and recreate it by closing, and reopening your pull request. ## Branching and hosting providers Branching works with hosting providers that support preview deployments. With the Supabase branching integration, you can sync the Git branch used by the hosting provider with the corresponding Supabase preview branch. This means that the preview deployment built by your hosting provider is matched to the correct database schema, edge functions, and other Supabase configurations. ### Vercel Install the Vercel integration: * From the [Vercel marketplace](https://vercel.com/integrations/supabase) or * By clicking the blue `Deploy` button in a Supabase example app's `README` file And make sure you have [connected](/dashboard/org/_/integrations) your Supabase project to your Vercel project. Supabase automatically updates your Vercel project with the correct environment variables for the corresponding preview branches. The synchronization happens at the time of Pull Request being opened, not at the time of branch creation. As branching integration is tied to the Preview Deployments feature in Vercel, there are possible race conditions between Supabase setting correct variables, and Vercel running a deployment process. Because of that, Supabase is always automatically re-deploying the most recent deployment of the given pull request. ## Other Git providers There are multiple alternative Git providers under consideration. If you're interested in branching for GitLab, Bitbucket, or some other provider, [join the GitHub discussion](https://github.com/orgs/supabase/discussions/18938). ## Alternatives to branching Under the hood, you can see Supabase branching as a way to programmatically "duplicate" your Supabase project via git flow. This allows spawning a new configured (via [`config.toml`](/docs/guides/local-development/cli/config)) and seeded instance of the database and the adjacent Supabase services (buckets, edge functions, etc.). 1. A new project is deployed on behalf of the user on the Supabase side as the new "branch" if it doesn't already exist. This includes the database, storage, edge-function, and all Supabase-related services. 2. The branch is cloned and the new project is configured based on the [`config.toml`](/docs/guides/local-development/cli/config) committed into this project branch. 3. Migrations are applied and seeding scripts are run (the first time) for this branch. You can make a similar setup with a distinct project for each environment. Or just have two environments, the localhost and the production one. ## Pricing Branching is available on the Pro Plan and above. The price is: * Each Preview branch costs $0.32 per day * Each Preview branch is billed until it is removed ## Troubleshooting ### Rolling back migrations You might want to roll back changes you've made in an earlier migration change. For example, you may have pushed a migration file containing schema changes you no longer want. To fix this, push the latest changes, then delete the preview branch in Supabase and reopen it. The new preview branch is reseeded from the `./supabase/seed.sql` file by default. Any additional data changes made on the old preview branch are lost. This is equivalent to running `supabase db reset` locally. All migrations are rerun in sequential order. ### Deployment failures A deployment might fail for various reasons, including invalid SQL statements and schema conflicts in migrations, errors within the `config.toml` config, or something else. To check the error message, see the Supabase workflow run for your branch under the [View logs](/dashboard/project/_/branches) section. ### Network restrictions If you enable [network restrictions](/docs/guides/platform/network-restrictions) on your project, the branching cluster will be blocked from connecting to your project by default. This often results in database connection failures when migrating your production project after merging a development branch. The workaround is to explicitly allow the IPv6 CIDR range of the branching cluster in your project's [database settings](https://supabase.com/dashboard/project/_/settings/database) page: `2600:1f18:2b7d:f600::/56` ### Schema drift between preview branches If multiple preview branches exist, each preview branch might contain different schema changes. This is similar to Git branches, where each branch might contain different code changes. When a preview branch is merged into the production branch, it creates a schema drift between the production branch and the preview branches that haven't been merged yet. These conflicts can be resolved in the same way as normal Git Conflicts: merge or rebase from the production Git branch to the preview Git branch. Since migrations are applied sequentially, ensure that migration files are timestamped correctly after the rebase. Changes that build on top of earlier changes should always have later timestamps. ### Changing production branch It's not possible to change the Git branch used as the Production branch for Supabase Branching. The only way to change it is to disable and re-enable branching. See [Disable Branching](#disable-branching). ## Feedback Supabase branching is a new and exciting part of the Supabase development ecosystem. Feedback is welcome. You can join the [conversation over in GitHub discussions](https://github.com/orgs/supabase/discussions/18937). # Database Migrations How to manage schema migrations for your Supabase project. Database migrations are SQL statements that create, update, or delete your existing database schemas. They are a common way of tracking changes to your database over time. ## Schema migrations For this guide, we'll create a table called `employees` and see how we can make changes to it. You will need to [install](/docs/guides/local-development#quickstart) the Supabase CLI and start the local development stack. Finally, you should see the `department` column added to your `employees` table in the local Dashboard. ### Seeding data Now that you are managing your database with migrations scripts, it would be great have some seed data to use every time you reset the database. You should now see the `employees` table, along with your seed data in the Dashboard! All of your database changes are captured in code, and you can reset to a known state at any time, complete with seed data. ### Diffing changes This workflow is great if you know SQL and are comfortable creating tables and columns. If not, you can still use the Dashboard to create tables and columns, and then use the CLI to diff your changes and create migrations. The last step is deploying these changes to a live Supabase project. ## Deploy your project You've been developing your project locally, making changes to your tables via migrations. It's time to deploy your project to the Supabase Platform and start scaling up to millions of users! Head over to [Supabase](https://supabase.com/dashboard) and create a new project to deploy to. Visiting your live project on [Supabase](https://supabase.com/dashboard/project/_), you'll see a new `employees` table, complete with the `department` column you added in the second migration above. # Production Checklist After developing your project and deciding it's Production Ready, you should run through this checklist to ensure that your project: * is secure * won't falter under the expected load * remains available whilst in production ## Security * Ensure RLS is enabled * Tables that do not have RLS enabled with reasonable policies allow any client to access and modify their data. This is unlikely to be what you want in the majority of cases. * [Learn more about RLS](/docs/guides/database/postgres/row-level-security). * Enable replication on tables containing sensitive data by enabling Row Level Security (RLS) and setting row security policies: * Go to the Authentication > Policies page in the Supabase Dashboard to enable RLS and create security policies. * Go to the Database > Publications page in the Supabase Dashboard to manage replication tables. * Turn on [SSL Enforcement](/docs/guides/platform/ssl-enforcement) * Enable [Network Restrictions](/docs/guides/platform/network-restrictions) for your database. * Ensure that your Supabase Account is protected with multi-factor authentication (MFA). * If using a GitHub signin, [enable 2FA on GitHub](https://docs.github.com/en/authentication/securing-your-account-with-two-factor-authentication-2fa/configuring-two-factor-authentication). Since your GitHub account gives you administrative rights to your Supabase org, you should protect it with a strong password and 2FA using a U2F key or a TOTP app. * If using email+password signin, set up [MFA for your Supabase account](https://supabase.com/docs/guides/platform/multi-factor-authentication#enable-mfa). * Consider [adding multiple owners on your Supabase org](https://supabase.com/dashboard/org/_/team). This ensures that if one of the owners is unreachable or loses access to their account, you still have Owner access to your org. * Ensure email confirmations are [enabled](https://supabase.com/dashboard/project/_/auth/providers) in the `Settings > Auth` page. * Ensure that you've [set the expiry](https://supabase.com/dashboard/project/_/auth/providers) for one-time passwords (OTPs) to a reasonable value that you are comfortable with. We recommend setting this to 3600 seconds (1 hour) or lower. * Increase the length of the OTP if you need a higher level of entropy. * If your application requires a higher level of security, consider setting up [multi-factor authentication](https://supabase.com/docs/guides/auth/auth-mfa) (MFA) for your users. * Use a custom SMTP server for auth emails so that your users can see that the mails are coming from a trusted domain (preferably the same domain that your app is hosted on). Grab SMTP credentials from any major email provider such as SendGrid, AWS SES, etc. * Think hard about how *you* would abuse your service as an attacker, and mitigate. * Review these [common cybersecurity threats](https://auth0.com/docs/security/prevent-threats). * Check and review issues in your database using [Security Advisor](https://supabase.com/dashboard/project/_/database/security-advisor). ## Performance * Ensure that you have suitable indices to cater to your common query patterns * [Learn more about indexes in Postgres](https://www.enterprisedb.com/postgres-tutorials/overview-postgresql-indexes). * `pg_stat_statements` can help you [identify hot or slow queries](https://www.virtual-dba.com/blog/postgresql-performance-identifying-hot-and-slow-queries/). * Perform load testing (preferably on a staging env) * Tools like [k6](https://k6.io/) can simulate traffic from many different users. * Upgrade your database if you require more resources. If you need anything beyond what is listed, contact enterprise@supabase.io. * If you are expecting a surge in traffic (for a big launch) and are on a Team or Enterprise Plan, [contact support](https://supabase.com/dashboard/support/new) with more details about your launch and we'll help keep an eye on your project. * If you expect your database size to be > 4 GB, [enable](https://supabase.com/dashboard/project/_/settings/addons?panel=pitr) the Point in Time Recovery (PITR) add-on. Daily backups can take up resources from your database when the backup is in progress. PITR is more resource efficient, since only the changes to the database are backed up. * Check and review issues in your database using [Performance Advisor](https://supabase.com/dashboard/project/_/database/performance-advisor). ## Availability * Use your own SMTP credentials so that you have full control over the deliverability of your transactional auth emails (see Settings > Auth) * you can grab SMTP credentials from any major email provider such as SendGrid, AWS SES, etc. You can refer to our [SMTP guide](/docs/guides/auth/auth-smtp) for more details. * The default rate limit for auth emails when using a custom SMTP provider is 30 new users per hour, if doing a major public announcement you will likely require more than this. * Applications on the Free Plan that exhibit extremely low activity in a 7 day period may be paused by Supabase to save on server resources. * You can restore paused projects from the Supabase dashboard. * Upgrade to Pro to guarantee that your project will not be paused for inactivity. * Database backups are not available for download on the Free Plan. * You can set up your own backup systems using tools like [pg\_dump](https://www.postgresqltutorial.com/postgresql-backup-database/) or [wal-g](https://github.com/wal-g/wal-g). * Nightly backups for Pro Plan projects are available on the Supabase dashboard for up to 7 days. * Point in Time Recovery (PITR) allows a project to be backed up at much shorter intervals. This provides users an option to restore to any chosen point of up to seconds in granularity. In terms of Recovery Point Objective (RPO), Daily Backups would be suitable for projects willing to lose up to 24 hours worth of data. If a lower RPO is required, enable PITR. * Supabase Projects use disks that offer 99.8-99.9% durability by default. * Use Read Replicas if you require availability resilience to a disk failure event * Use PITR if you require durability resilience to a disk failure event * Upgrading to the Supabase Pro Plan will give you [access to our support team](https://supabase.com/dashboard/support/new). ## Rate limiting, resource allocation, & abuse prevention * Supabase employs a number of safeguards against bursts of incoming traffic to prevent abuse and help maximize stability across the platform * If you're on a Team or Enterprise Plan and expect high load events, such as production launches, heavy load testing, or prolonged high resource usage, open a ticket via the [support form](https://supabase.help) for help. Provide at least 2 weeks notice. ### Auth rate limits * The table below shows the rate limit quotas on the following authentication endpoints. You can configure the auth rate limits for your project [here](/dashboard/project/_/auth/rate-limits). | Endpoint | Path | Limited By | Rate Limit | | ------------------------------------------------ | -------------------------------------------------------------- | ------------------------ | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- | | All endpoints that send emails | `/auth/v1/signup` `/auth/v1/recover` `/auth/v1/user`\[^1] | Sum of combined requests | As of 3 Sep 2024, this has been updated to emails per hour. You can only change this with your own [custom SMTP setup](/docs/guides/auth/auth-smtp). | | All endpoints that send One-Time-Passwords (OTP) | `/auth/v1/otp` | Sum of combined requests | Defaults to 360 OTPs per hour. Is customizable. | | Send OTPs or magic links | `/auth/v1/otp` | Last request | Defaults to 60 seconds window before a new request is allowed. Is customizable. | | Signup confirmation request | `/auth/v1/signup` | Last request | Defaults to 60 seconds window before a new request is allowed. Is customizable. | | Password Reset Request | `/auth/v1/recover` | Last request | Defaults to 60 seconds window before a new request is allowed. Is customizable. | | Verification requests | `/auth/v1/verify` | IP Address | 360 requests per hour (with bursts up to 30 requests) | | Token refresh requests | `/auth/v1/token` | IP Address | 1800 requests per hour (with bursts up to 30 requests) | | Create or Verify an MFA challenge | `/auth/v1/factors/:id/challenge` `/auth/v1/factors/:id/verify` | IP Address | 15 requests per minute (with bursts up to 30 requests) | | Anonymous sign-ins | `/auth/v1/signup`\[^2] | IP Address | 30 requests per hour (with bursts up to 30 requests) | ### Realtime quotas * Review the [Realtime quotas](/docs/guides/realtime/quotas). * If you need quotas increased you can always [contact support](https://supabase.com/dashboard/support/new). ### Abuse prevention * Supabase provides CAPTCHA protection on the signup, sign-in and password reset endpoints. Refer to [our guide](/docs/guides/auth/auth-captcha) on how to protect against abuse using this method. ### Email link validity * When working with enterprise systems, email scanners may scan and make a `GET` request to the reset password link or sign up link in your email. Since links in Supabase Auth are single use, a user who opens an email post-scan to click on a link will receive an error. To get around this problem, consider altering the email template to replace the original magic link with a link to a domain you control. The domain can present the user with a "Sign-in" button which redirect the user to the original magic link URL when clicked. * When using a custom SMTP service, some services might have link tracking enabled which may overwrite or disform the email confirmation links sent by Supabase Auth. To prevent this from happening, we recommend that you disable link tracking when using a custom SMTP service. ## Subscribe to Supabase status page Stay informed about Supabase service status by subscribing to the [Status Page](https://status.supabase.com/). We recommend setting up Slack notifications through an RSS feed to ensure your team receives timely updates about service status changes. ### Setting up Slack notifications 1. Install the RSS app in Slack: * Visit the [RSS app page](https://slack.com/marketplace/A0F81R7U7-rss) in the Slack marketplace * Click `Add to Slack` if not already installed * Otherwise you will get straight to next step, no need to reinstall the app 2. Configure the Supabase status feed: * Create a channel (e.g., `#supabase-status-alerts`) for status updates * On the [RSS app page](https://slack.com/marketplace/A0F81R7U7-rss) go to *Add a Feed* section and set Feed URL to `https://status.supabase.com/history.rss` * Select your designated channel and click "Subscribe to this feed" Once configured, your team will receive automatic notifications in Slack whenever the Supabase Status Page is updated. For detailed setup instructions, see the [Add RSS feeds to Slack](https://slack.com/intl/en-nz/help/articles/218688467-Add-RSS-feeds-to-Slack). ## Next steps This checklist is always growing so be sure to check back frequently, and also feel free to suggest additions and amendments by making a PR on [GitHub](https://github.com/supabase/supabase). # Managing Environments Manage multiple environments using Database Migrations and GitHub Actions. This guide shows you how to set up your local Supabase development environment that integrates with GitHub Actions to automatically test and release schema changes to staging and production Supabase projects. ## Set up a local environment The first step is to set up your local repository with the Supabase CLI: ```bash supabase init ``` You should see a new `supabase` directory. Then you need to link your local repository with your Supabase project: ```bash supabase login supabase link --project-ref $PROJECT_ID ``` You can get your `$PROJECT_ID` from your project's dashboard URL: https://supabase.com/dashboard/project/ If you're using an existing Supabase project, you might have made schema changes through the Dashboard. Run the following command to pull these changes before making local schema changes from the CLI: ```sql supabase db pull ``` This command creates a new migration in `supabase/migrations/_remote_schema.sql` which reflects the schema changes you have made previously. Now commit your local changes to Git and run the local development setup: ```bash git add . git commit -m "init supabase" supabase start ``` You are now ready to develop schema changes locally and create your first migration. ## Create a new migration There are two ways to make schema changes: 1. Manual migration: Write DDL statements manually into a migration file 2. Auto schema diff: Make changes through Studio UI and auto generate a schema diff ### Manual migration Create a new migration script by running: ```bash supabase migration new new_employee ``` You should see a new file created: `supabase/migrations/_new_employee.sql`. You can then write SQL statements in this script using a text editor: ```sql create table public.employees ( id integer primary key generated always as identity, name text ); ``` Apply the new migration to your local database: ```bash supabase db reset ``` This command recreates your local database from scratch and applies all migration scripts under `supabase/migrations` directory. Now your local database is up to date. ### Auto schema diff Unlike manual migrations, auto schema diff creates a new migration script from changes **already** applied to your local database. Create an `employees` table under the `public` schema using Studio UI, accessible at [localhost:54323](http://localhost:54323/) by default. Next, generate a schema diff by running the following command: ```bash supabase db diff -f new_employee ``` You should see that a new file `supabase/migrations/_new_employee.sql` is created. Open the file and verify that the generated DDL statements are the same as below. ```sql -- This script was generated by the Schema Diff utility in pgAdmin 4 -- For the circular dependencies, the order in which Schema Diff writes the objects is not very sophisticated -- and may require manual changes to the script to ensure changes are applied in the correct order. -- Please report an issue for any failure with the reproduction steps. CREATE TABLE IF NOT EXISTS public.employees ( id integer NOT NULL GENERATED ALWAYS AS IDENTITY ( INCREMENT 1 START 1 MINVALUE 1 MAXVALUE 2147483647 CACHE 1 ), name text COLLATE pg_catalog."default", CONSTRAINT employees_pkey PRIMARY KEY (id) ) TABLESPACE pg_default; ALTER TABLE IF EXISTS public.employees OWNER to postgres; GRANT ALL ON TABLE public.employees TO anon; GRANT ALL ON TABLE public.employees TO authenticated; GRANT ALL ON TABLE public.employees TO postgres; GRANT ALL ON TABLE public.employees TO service_role; ``` You may notice that the auto-generated migration script is more verbose than the manually written one. This is because the default schema diff tool does not account for default privileges added by the initial schema. Commit the new migration script to git and you are ready to deploy. ## Deploy a migration In a production environment, we recommend using a CI/CD pipeline to deploy new migrations with GitHub Actions rather than deploying from your local machine. This example uses two Supabase projects, one for production and one for staging. Prepare your environments by: * Creating separate Supabase projects for staging and production * Pushing your git repository to GitHub and enabling GitHub Actions ### Configure GitHub Actions The Supabase CLI requires a few environment variables to run in non-interactive mode. * `SUPABASE_ACCESS_TOKEN` is your personal access token * `SUPABASE_DB_PASSWORD` is your project specific database password * `SUPABASE_PROJECT_ID` is your project specific reference string We recommend adding these as [encrypted secrets](https://docs.github.com/en/actions/security-guides/encrypted-secrets) to your GitHub Actions runners. Create the following files inside the `.github/workflows` directory: The full example code is available in the [demo repository](https://github.com/supabase/supabase-action-example). Commit these files to git and push to your `main` branch on GitHub. Update these environment variables to match your Supabase projects: * `SUPABASE_ACCESS_TOKEN` * `PRODUCTION_PROJECT_ID` * `PRODUCTION_DB_PASSWORD` * `STAGING_PROJECT_ID` * `STAGING_DB_PASSWORD` When configured correctly, your repository will have CI and Release workflows that trigger on new commits pushed to `main` and `develop` branches. ![Correctly configured repo](/docs/img/guides/cli/ci-main.png) ### Open a PR with new migration Follow the [migration steps](#create-a-new-migration) to create a `supabase/migrations/_new_employee.sql` file. Checkout a new branch `feat/employee` from `develop` , commit the migration file, and push to GitHub. ```bash git checkout -b feat/employee git add supabase/migrations/_new_employee.sql git commit -m "Add employee table" git push --set-upstream origin feat/employee ``` Open a PR from `feat/employee` to the `develop` branch to see that the CI workflow has been triggered. Once the test error is resolved, merge this PR and watch the deployment in action. ### Release to production After verifying your staging project has successfully migrated, create another PR from `develop` to `main` and merge it to deploy the migration to the production project. The `release` job applies all new migration scripts merged in `supabase/migrations` directory to a linked Supabase project. You can control which project the job links to via `PROJECT_ID` environment variable. ## Troubleshooting ### Sync production project to staging When setting up a new staging project, you might need to sync the initial schema with migrations previously applied to the production project. One way is to leverage the Release workflow: * Create a new branch `develop` and choose `main` as the branch source * Push the `develop` branch to GitHub The GitHub Actions runner will deploy your existing migrations to the staging project. Alternatively, you can also apply migrations through your local CLI to a linked remote database. ```sql supabase db push ``` Once pushed, check that the migration version is up to date for both local and remote databases. ```sql supabase migration list ``` ### Permission denied on `db pull` If you have been using Supabase hosted projects for a long time, you might encounter the following permission error when executing `db pull`. ```bash Error: Error running pg_dump on remote database: pg_dump: error: query failed: ERROR: permission denied for table _type pg_dump: error: query was: LOCK TABLE "graphql"."_type" IN ACCESS SHARE MODE ``` To resolve this error, you need to grant `postgres` role permissions to `graphql` schema. You can do that by running the following query from Supabase dashboard's SQL Editor. ```sql grant all on all tables in schema graphql to postgres, anon, authenticated, service_role; grant all on all functions in schema graphql to postgres, anon, authenticated, service_role; grant all on all sequences in schema graphql to postgres, anon, authenticated, service_role; ``` ### Permission denied on `db push` If you created a table through Supabase dashboard, and your new migration script contains `ALTER TABLE` statements, you might run into permission error when applying them on staging or production databases. ```bash ERROR: must be owner of table employees (SQLSTATE 42501); while executing migration ``` This is because tables created through Supabase dashboard are owned by `supabase_admin` role while the migration scripts executed through CLI are under `postgres` role. One way to solve this is to reassign the owner of those tables to `postgres` role. For example, if your table is named `users` in the public schema, you can run the following command to reassign owner. ```sql ALTER TABLE users OWNER TO postgres; ``` Apart from tables, you also need to reassign owner of other entities using their respective commands, including [types](https://www.postgresql.org/docs/current/sql-altertype.html), [functions](https://www.postgresql.org/docs/current/sql-alterroutine.html), and [schemas](https://www.postgresql.org/docs/current/sql-alterschema.html). ### Rebasing new migrations Sometimes your teammate may merge a new migration file to git main branch, and now you need to rebase your local schema changes on top. We can handle this scenario gracefully by renaming your old migration file with a new timestamp. ```bash git pull supabase migration new dev_A # Assume the new file is: supabase/migrations/_dev_A.sql mv