• Stars
    star
    165
  • Rank 220,607 (Top 5 %)
  • Language PLpgSQL
  • License
    Apache License 2.0
  • Created almost 3 years ago
  • Updated about 1 month ago

Reviews

There are no reviews yet. Be the first to send feedback to the community and the maintainers!

Repository Details

A PostgreSQL extension that enables asynchronous (non-blocking) HTTP/HTTPS requests with SQL

PG_NET

A PostgreSQL extension that enables asynchronous (non-blocking) HTTP/HTTPS requests with SQL

PostgreSQL version License Tests

Documentation: https://supabase.github.io/pg_net


Contents


Introduction

The PG_NET extension enables PostgreSQL to make asynchronous HTTP/HTTPS requests in SQL. 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. It seamlessly integrates with triggers, cron jobs (e.g., PG_CRON), and procedures, unlocking numerous possibilities. Notably, PG_NET powers Supabase's Webhook functionality, highlighting its robustness and reliability.

Common use cases for the PG_NET extension include:

  • Calling external APIs
  • Syncing data with outside resources
  • Calling a serverless function when an event, such as an insert, occurred

However, it is important to note that the extension has a few limitations. Currently, it only supports three types of asynchronous requests:

  • async http GET requests
  • async http POST requests with a JSON payload
  • async http DELETE requests

Ultimately, though, PG_NET offers developers more flexibility in how they monitor and connect their database with external resources.


Technical Explanation

The extension introduces a new net schema, which contains two unlogged tables, a type of table in PostgreSQL that offers performance improvements at the expense of durability. You can read more about unlogged tables here. The two tables are:

  1. http_request_queue: This table serves as a queue for requests waiting to be executed. Upon successful execution of a request, the corresponding data is removed from the queue.

    The SQL statement to create this table is:

    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
        )
  2. _http_response: This table holds the responses of each executed request.

    The SQL statement to create this table is:

    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()
        )

When any of the three request functions (http_get, http_post, http_delete) are invoked, they create an entry in the net.http_request_queue table.

The extension employs C's libCurl library within a PostgreSQL background worker to manage HTTP requests. This background worker regularly checks the http_request_queue table and executes the requests it finds there.

Once a response is received, it gets stored in the _http_response table. By monitoring this table, you can keep track of response statuses and messages.


Installation

Enabling the Extension with Supabase

You can activate the pg_net extension via Supabase's dashboard by following these steps:

  1. Navigate to the 'Database' page.
  2. Select 'Extensions' from the sidebar.
  3. Search for "pg_net" and enable the extension.

Local Setup

Configuring Your Device/Server

Clone this repo and run

make && make install

To make the extension available to the database add on postgresql.conf:

shared_preload_libraries = 'pg_net'

By default, pg_net is available on the postgres database. To use pg_net on a different database, you can add the following on postgresql.conf:

pg_net.database_name = '<dbname>';

Using pg_net on multiple databases in a cluster is not supported.

Installing in PostgreSQL

To activate the extension in PostgreSQL, run the create extension command. The extension creates its own schema named net to avoid naming conflicts.

create extension pg_net;

Requests API

Monitoring Requests

When you call a request function (http_get, http_post, http_delete), the function will return a request_id immediately. You can use this request_id with the net._http_collect_response function to check the results of your request. This function returns a custom type _net.http_response_result* that has three columns:

  1. response: This is an aggregate of the response's status_code (integer), headers (JSONB), and body (text).
  2. status: This value indicates the execution status of the request itself, which can be either 'PENDING', 'SUCCESS', or 'ERROR'. It's important not to confuse this status with the HTTP status code of the response (like 200 for 'OK', 404 for 'Not Found', etc.) that is found in the response column
  3. message: This contains the response's message as text.

Observing a Request's Response

SELECT
    message,
    response,
    status
FROM
    net._http_collect_response(<response_id>);

WARNING: Although the status column can be 'PENDING', 'SUCCESS', or 'ERROR', there is a bug that makes all 'PENDING' requests displayed as 'ERROR'.

The individual values within the response column can be extracted as shown in the following SQL query:

Extracting response values

SELECT
    *,
    (response).status_code,
    (response).headers,
    (response).body
    -- Individual headers and values from the body can be extracted
    (((response).body::JSON)->'key-from-json-body') AS some_value
FROM
    net._http_collect_response(<request_id>);

GET requests

net.http_get function signature

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 cancelled
    timeout_milliseconds int default 1000
)
    -- request_id reference
    returns bigint

    strict
    volatile
    parallel safe
    language plpgsql

Examples:

The following examples use the Postman Echo API.

Calling an API

SELECT net.http_get (
    'https://postman-echo.com/get?foo1=bar1&foo2=bar2'
) AS request_id;

NOTE: You can view the response with the following query:

SELECT
    *,
    ((response).body::JSON)->'args' AS args
FROM
    net._http_collect_response(<response_id>);

Calling an API with URL encoded params

SELECT net.http_get(
  'https://postman-echo.com/get',
  -- Equivalent to calling https://postman-echo.com/get?foo1=bar1&foo2=bar2&encoded=%21
  -- The "!" is url-encoded as %21
  '{"foo1": "bar1", "foo2": "bar2", "encoded": "!"}'::JSONB
) AS request_id;

Calling an API with an API-KEY

SELECT net.http_get(
  'https://postman-echo.com/get?foo1=bar1&foo2=bar2',
   headers := '{"API-KEY-HEADER": "<API KEY>"}'::JSONB
) AS request_id;

POST requests

net.http_post function signature

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 cancelled
    timeout_milliseconds int default 1000
)
    -- request_id reference
    returns bigint

    volatile
    parallel safe
    language plpgsql

Examples:

The following examples post to the Postman Echo API.

Sending data to an API

SELECT net.http_post(
    'https://postman-echo.com/post',
    '{"key": "value", "key": 5}'::JSONB,
    headers := '{"API-KEY-HEADER": "<API KEY>"}'::JSONB
) AS request_id;

Sending single table row as a payload

NOTE: If multiple rows are sent using this method, each row will be sent as a separate request.

WITH selected_row AS (
    SELECT
        *
    FROM target_table
    LIMIT 1
)
SELECT
    net.http_post(
        'https://postman-echo.com/post',
        to_jsonb(selected_row.*),
        headers := '{"API-KEY-HEADER": "<API KEY>"}'::JSONB
    ) AS request_id
FROM selected_row;

Sending multiple table rows as a payload

WARNING: when sending multiple rows, be careful to limit your payload size.

WITH selected_rows AS (
    SELECT
        -- Converts all the rows into a JSONB array
        jsonb_agg(to_jsonb(target_table)) AS JSON_payload
    FROM target_table
    -- Generally good practice to LIMIT the max amount of rows
)
SELECT
    net.http_post(
        'https://postman-echo.com/post'::TEXT,
        JSON_payload,
        headers := '{"API-KEY-HEADER": "<API KEY>"}'::JSONB
    ) AS request_id
FROM selected_rows;

DELETE requests

net.http_delete function signature

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 cancelled
    timeout_milliseconds int default 2000
)
    -- request_id reference
    returns bigint

    strict
    volatile
    parallel safe
    language plpgsql
    security definer

Examples:

The following examples use the Dummy Rest API.

Sending a delete request to an API

SELECT net.http_delete(
    'https://dummy.restapiexample.com/api/v1/delete/2'
) AS request_id;

Sending a delete request with a row id as a query param

WITH selected_id AS (
    SELECT
        id
    FROM target_table
    LIMIT 1 -- if not limited, it will make a delete request for each returned row
)
SELECT
    net.http_delete(
        'https://dummy.restapiexample.com/api/v1/delete/'::TEXT,
        format('{"id": "%s"}', id)::JSONB
    ) AS request_id
FROM selected_id;

Sending a delete request with a row id as a path param

WITH selected_id AS (
    SELECT
        id
    FROM target_table
    LIMIT 1 -- if not limited, it will make a delete request for each returned row
)
SELECT
    net.http_delete(
        'https://dummy.restapiexample.com/api/v1/delete/' || id
    ) AS request_id
FROM selected_row

Practical Examples

Syncing data with an external data source using triggers

The following example comes from Typesense's Supabase Sync guide

-- Create the function to delete the record from Typesense
CREATE OR REPLACE FUNCTION delete_record()
    RETURNS TRIGGER
    LANGUAGE plpgSQL
AS $$
BEGIN
    SELECT net.http_delete(
        url := format('<TYPESENSE URL>/collections/products/documents/%s', OLD.id),
        headers := '{"X-Typesense-API-KEY": "<Typesense_API_KEY>"}'
    )
    RETURN OLD;
END $$;

-- Create the trigger that calls the function when a record is deleted from the products table
CREATE TRIGGER delete_products_trigger
    AFTER DELETE ON public.products
    FOR EACH ROW
    EXECUTE FUNCTION delete_products();

Calling a serverless function every minute with PG_CRON

The PG_CRON extension enables PostgreSQL to become its own cron server. With it you can schedule regular calls to activate serverless functions.

Useful links:

Example Cron job to call serverless function

SELECT cron.schedule(
	'cron-job-name',
	'* * * * *', -- Executes every minute (cron syntax)
	$$
	    -- SQL query
	    SELECT net.http_get(
		-- URL of Edge function
		url:='https://<reference id>.functions.Supabase.co/example',
		headers:='{
		    "Content-Type": "application/json",
		    "Authorization": "Bearer <TOKEN>"
		}'::JSONB
	    ) as request_id;
	$$
);

Retrying failed requests

Every request made is logged within the net._http_response table. To identify failed requests, you can execute a query on the table, filtering for requests where the status code is 500 or higher.

Finding failed requests

SELECT
    *
FROM net._http_response
WHERE status_code >= 500;

While the net._http_response table logs each request, it doesn't store all the necessary information to retry failed requests. To facilitate this, we need to create a request tracking table and a wrapper function around the PG_NET request functions. This will help us store the required details for each request.

Creating a Request Tracker Table

CREATE TABLE request_tracker(
    method TEXT,
    url TEXT,
    params JSONB,
    body JSONB,
    headers JSONB,
    request_id BIGINT
)

Below is a function called request_wrapper, which wraps around the PG_NET request functions. This function records every request's details in the request_tracker table, facilitating future retries if needed.

Creating a Request Wrapper Function

CREATE OR REPLACE FUNCTION request_wrapper(
    method TEXT,
    url TEXT,
    params JSONB DEFAULT '{}'::JSONB,
    body JSONB DEFAULT '{}'::JSONB,
    headers JSONB DEFAULT '{}'::JSONB
)
RETURNS BIGINT
AS $$
DECLARE
    request_id BIGINT;
BEGIN

    IF method = 'DELETE' THEN
        SELECT net.http_delete(
            url:=url,
            params:=params,
            headers:=headers
        ) INTO request_id;
    ELSIF method = 'POST' THEN
        SELECT net.http_post(
            url:=url,
            body:=body,
            params:=params,
            headers:=headers
        ) INTO request_id;
    ELSIF method = 'GET' THEN
        SELECT net.http_get(
            url:=url,
            params:=params,
            headers:=headers
        ) INTO request_id;
    ELSE
        RAISE EXCEPTION 'Method must be DELETE, POST, or GET';
    END IF;

    INSERT INTO request_tracker (method, url, params, body, headers, request_id)
    VALUES (method, url, params, body, headers, request_id);

    RETURN request_id;
END;
$$
LANGUAGE plpgsql;

To retry a failed request recorded via the wrapper function, use the following query. This will select failed requests, retry them, and then remove the original request data from both the net._http_response and request_tracker tables.

Retrying failed requests

WITH retry_request AS (
    SELECT
        request_tracker.method,
        request_tracker.url,
        request_tracker.params,
        request_tracker.body,
        request_tracker.headers,
        request_tracker.request_id
    FROM request_tracker
    INNER JOIN net._http_response ON net._http_response.id = request_tracker.request_id
    WHERE net._http_response.status_code >= 500
    LIMIT 3
),
retry AS (
    SELECT
        request_wrapper(retry_request.method, retry_request.url, retry_request.params, retry_request.body, retry_request.headers)
    FROM retry_request
),
delete_http_response AS (
    DELETE FROM net._http_response
    WHERE id IN (SELECT request_id FROM retry_request)
    RETURNING *
)
DELETE FROM request_tracker
WHERE request_id IN (SELECT request_id FROM retry_request)
RETURNING *;

The above function can be called using cron jobs or manually to retry failed requests. It may also be beneficial to clean the request_tracker table in the process.

Contributing

Checkout the Contributing page to learn more about adding to the project.

More Repositories

1

supabase

The open source Firebase alternative.
TypeScript
65,693
star
2

realtime

Broadcast, Presence, and Postgres Changes via WebSockets
Elixir
6,458
star
3

postgres_lsp

A Language Server for Postgres
Rust
3,073
star
4

supabase-js

An isomorphic Javascript client for Supabase. Query your Supabase database, subscribe to realtime events, upload and download files, browse typescript examples, invoke postgres functions via rpc, invoke supabase edge functions, query pgvector.
TypeScript
2,795
star
5

pg_graphql

GraphQL support for PostgreSQL
Rust
2,760
star
6

supavisor

A cloud-native, multi-tenant Postgres connection pooler.
Elixir
1,574
star
7

ui

Supabase UI Library
TypeScript
1,510
star
8

postgres

Unmodified Postgres with some useful plugins
Shell
1,265
star
9

index_advisor

PostgreSQL Index Advisor
PLpgSQL
1,263
star
10

auth

A JWT based API for managing users and issuing JWT tokens
Go
1,159
star
11

pg_jsonschema

PostgreSQL extension providing JSON Schema validation
Rust
929
star
12

postgrest-js

Isomorphic JavaScript client for PostgREST.
TypeScript
917
star
13

auth-helpers

A collection of framework specific Auth utilities for working with Supabase.
TypeScript
877
star
14

cli

Supabase CLI. Manage postgres migrations, run Supabase locally, deploy edge functions. Postgres backups. Generating types from your database schema.
Go
849
star
15

postgres-meta

A RESTful API for managing your Postgres. Fetch tables, add roles, and run queries
TypeScript
820
star
16

storage

S3 compatible object storage service that stores metadata in Postgres
TypeScript
640
star
17

supabase-flutter

Flutter integration for Supabase. This package makes it simple for developers to build secure and scalable products.
Dart
613
star
18

supa_audit

Generic Table Auditing
PLpgSQL
611
star
19

supabase-swift

A Swift client for Supabase
Swift
583
star
20

edge-runtime

A server based on Deno runtime, capable of running JavaScript, TypeScript, and WASM services.
Rust
557
star
21

stripe-sync-engine

Sync your Stripe account to you Postgres database.
TypeScript
457
star
22

wrappers

Postgres Foreign Data Wrapper development framework in Rust.
Rust
433
star
23

auth-ui

Pre-built Auth UI for React
TypeScript
405
star
24

supabase-dart

A Dart client for Supabase
Dart
402
star
25

pg_crdt

POC CRDT support in Postgres
Rust
372
star
26

dbdev

Database Package Registry for Postgres
PLpgSQL
329
star
27

auth-js

An isomorphic Javascript library for Supabase Auth.
CSS
298
star
28

realtime-js

An isomorphic Javascript client for Supabase Realtime server.
JavaScript
288
star
29

examples-archive

Supabase Examples Archive
TypeScript
278
star
30

pg_netstat

PostgreSQL extension to monitor database network traffic
Rust
246
star
31

grid

A react component to display your Postgresql table data. Used in Supabase Dashboard app.
TypeScript
197
star
32

vecs

Postgres/pgvector Python Client
Python
190
star
33

libcluster_postgres

Postgres strategy for libcluster
Elixir
178
star
34

vault

Extension for storing encrypted secrets in the Vault
PLpgSQL
161
star
35

postgrest-dart

Dart client for PostgREST
Dart
137
star
36

headless-vector-search

Supabase Toolkit to perform vector similarity search on your knowledge base embeddings.
TypeScript
135
star
37

workflows

Elixir
133
star
38

supabase-grafana

Observability for your Supabase project, using Prometheus/Grafana
Shell
132
star
39

walrus

Applying RLS to PostgreSQL WAL
PLpgSQL
117
star
40

storage-js

JS Client library to interact with Supabase Storage
TypeScript
111
star
41

postgres-deno

A PostgreSQL extension for Deno: run Typescript in PostgreSQL functions and triggers.
104
star
42

realtime-dart

A dart client for Supabase Realtime server.
Dart
85
star
43

setup-cli

A GitHub action for interacting with your Supabase projects using the CLI.
TypeScript
83
star
44

repository.surf

πŸ„
JavaScript
80
star
45

embeddings-generator

GitHub Action to generate embeddings from the markdown files in your repository.
TypeScript
79
star
46

supabase-ui-web

TypeScript
74
star
47

self-hosted-edge-functions-demo

A demo of how to self-host Supabase Edge Functions on Fly.io
TypeScript
61
star
48

functions-js

TypeScript
54
star
49

supabase-admin-api

API to administer the Supabase server (KPS)
Go
51
star
50

supautils

PostgreSQL extension that secures a cluster on a cloud environment
C
49
star
51

gotrue-dart

A dart client library for GoTrue.
Dart
47
star
52

supabase-action-example

TypeScript
45
star
53

benchmarks

SCSS
41
star
54

grafana-agent-fly-example

Deploy a Grafana Agent on Fly to scrape Prometheus metrics from Supabase and send them to Grafana Cloud
Shell
36
star
55

functions-relay

API Gateway for Supabase Edge functions
TypeScript
35
star
56

nix-postgres

Experimental port of supabase/postgres to Nix
Nix
35
star
57

benchmarks-archive

Infrastucture benchmarks
Nix
31
star
58

hibp

Go library for HaveIBeenPwned.org's pwned passwords API.
Go
29
star
59

splinter

Supabase Postgres Linter
PLpgSQL
28
star
60

supabase.ai

iykyk
HTML
27
star
61

storage-dart

Dart client library to interact with Supabase Storage
Dart
22
star
62

livebooks

A collection of Elixir Livebooks for Supabase
Dockerfile
20
star
63

base64url-js

Pure TypeScript implementation of Base64-URL encoding for JavaScript strings.
TypeScript
19
star
64

terraform-provider-supabase

Go
17
star
65

orb-sync-engine

TypeScript
12
star
66

.github

Org-wide default community health files & templates.
11
star
67

auth-elements

Components to add Supabase Auth to any application
TypeScript
11
star
68

rfcs

11
star
69

functions-dart

Dart
8
star
70

test-reports

Repository to store test reports data and host reporting in gh-pages
7
star
71

plug_caisson

An Elixir Plug library for handling compressed requests
Elixir
6
star
72

flyswatter

Deploy a global pinger on Fly
Elixir
6
star
73

scoop-bucket

4
star
74

tests

TypeScript
4
star
75

pgextkit

Rust
3
star
76

homebrew-tap

Ruby
3
star
77

fly-preview

TypeScript
3
star
78

shared-types

TypeScript
3
star
79

supa_type

The Missing PostgreSQL Data Types
Nix
3
star
80

test-inspector

Check your test results against the reference run and compare coverage for multiple client libraries
Go
2
star
81

mailme

A clone of Netlify's mailme package used in Supabase Auth / GoTrue.
Go
2
star
82

productions

Supabase SynthWave. The best soundtrack to build an app in a weekend and scale to billions.
TypeScript
1
star
83

design-tokens

1
star