From 1fd3dc3ca2c2a9761f5e33f596c18bc54006ecc0 Mon Sep 17 00:00:00 2001
From: Qiao Han <qiao@supabase.io>
Date: Thu, 22 Aug 2024 02:21:11 +0800
Subject: [PATCH 1/5] feat: enable webhooks by default

---
 ...40822021428_enable_webhooks_by_default.sql | 242 ++++++++++++++++++
 migrations/schema.sql                         | 188 ++++++++++++++
 2 files changed, 430 insertions(+)
 create mode 100644 migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql

diff --git a/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql b/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
new file mode 100644
index 000000000..1d5746437
--- /dev/null
+++ b/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
@@ -0,0 +1,242 @@
+-- migrate:up
+
+-- Create pg_net extension
+CREATE EXTENSION IF NOT EXISTS pg_net SCHEMA extensions;
+
+-- Create supabase_functions schema
+CREATE SCHEMA supabase_functions AUTHORIZATION supabase_admin;
+
+GRANT USAGE ON SCHEMA supabase_functions TO postgres, anon, authenticated, service_role;
+ALTER DEFAULT PRIVILEGES IN SCHEMA supabase_functions GRANT ALL ON TABLES TO postgres, anon, authenticated, service_role;
+ALTER DEFAULT PRIVILEGES IN SCHEMA supabase_functions GRANT ALL ON FUNCTIONS TO postgres, anon, authenticated, service_role;
+ALTER DEFAULT PRIVILEGES IN SCHEMA supabase_functions GRANT ALL ON SEQUENCES TO postgres, anon, authenticated, service_role;
+
+-- supabase_functions.migrations definition
+CREATE TABLE supabase_functions.migrations (
+  version text PRIMARY KEY,
+  inserted_at timestamptz NOT NULL DEFAULT NOW()
+);
+
+-- Initial supabase_functions migration
+INSERT INTO supabase_functions.migrations (version) VALUES ('initial');
+
+-- supabase_functions.hooks definition
+CREATE TABLE supabase_functions.hooks (
+  id bigserial PRIMARY KEY,
+  hook_table_id integer NOT NULL,
+  hook_name text NOT NULL,
+  created_at timestamptz NOT NULL DEFAULT NOW(),
+  request_id bigint
+);
+CREATE INDEX supabase_functions_hooks_request_id_idx ON supabase_functions.hooks USING btree (request_id);
+CREATE INDEX supabase_functions_hooks_h_table_id_h_name_idx ON supabase_functions.hooks USING btree (hook_table_id, hook_name);
+COMMENT ON TABLE supabase_functions.hooks IS 'Supabase Functions Hooks: Audit trail for triggered hooks.';
+
+CREATE FUNCTION supabase_functions.http_request()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $function$
+  DECLARE
+    request_id bigint;
+    payload jsonb;
+    url text := TG_ARGV[0]::text;
+    method text := TG_ARGV[1]::text;
+    headers jsonb DEFAULT '{}'::jsonb;
+    params jsonb DEFAULT '{}'::jsonb;
+    timeout_ms integer DEFAULT 1000;
+  BEGIN
+    IF url IS NULL OR url = 'null' THEN
+      RAISE EXCEPTION 'url argument is missing';
+    END IF;
+
+    IF method IS NULL OR method = 'null' THEN
+      RAISE EXCEPTION 'method argument is missing';
+    END IF;
+
+    IF TG_ARGV[2] IS NULL OR TG_ARGV[2] = 'null' THEN
+      headers = '{"Content-Type": "application/json"}'::jsonb;
+    ELSE
+      headers = TG_ARGV[2]::jsonb;
+    END IF;
+
+    IF TG_ARGV[3] IS NULL OR TG_ARGV[3] = 'null' THEN
+      params = '{}'::jsonb;
+    ELSE
+      params = TG_ARGV[3]::jsonb;
+    END IF;
+
+    IF TG_ARGV[4] IS NULL OR TG_ARGV[4] = 'null' THEN
+      timeout_ms = 1000;
+    ELSE
+      timeout_ms = TG_ARGV[4]::integer;
+    END IF;
+
+    CASE
+      WHEN method = 'GET' THEN
+        SELECT http_get INTO request_id FROM net.http_get(
+          url,
+          params,
+          headers,
+          timeout_ms
+        );
+      WHEN method = 'POST' THEN
+        payload = jsonb_build_object(
+          'old_record', OLD,
+          'record', NEW,
+          'type', TG_OP,
+          'table', TG_TABLE_NAME,
+          'schema', TG_TABLE_SCHEMA
+        );
+
+        SELECT http_post INTO request_id FROM net.http_post(
+          url,
+          payload,
+          params,
+          headers,
+          timeout_ms
+        );
+      ELSE
+        RAISE EXCEPTION 'method argument % is invalid', method;
+    END CASE;
+
+    INSERT INTO supabase_functions.hooks
+      (hook_table_id, hook_name, request_id)
+    VALUES
+      (TG_RELID, TG_NAME, request_id);
+
+    RETURN NEW;
+  END
+$function$;
+
+-- Supabase super admin
+DO
+$$
+BEGIN
+  IF NOT EXISTS (
+    SELECT 1
+    FROM pg_roles
+    WHERE rolname = 'supabase_functions_admin'
+  )
+  THEN
+    CREATE USER supabase_functions_admin NOINHERIT CREATEROLE LOGIN NOREPLICATION;
+  END IF;
+END
+$$;
+
+GRANT ALL PRIVILEGES ON SCHEMA supabase_functions TO supabase_functions_admin;
+GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA supabase_functions TO supabase_functions_admin;
+GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA supabase_functions TO supabase_functions_admin;
+ALTER USER supabase_functions_admin SET search_path = "supabase_functions";
+ALTER table "supabase_functions".migrations OWNER TO supabase_functions_admin;
+ALTER table "supabase_functions".hooks OWNER TO supabase_functions_admin;
+ALTER function "supabase_functions".http_request() OWNER TO supabase_functions_admin;
+GRANT supabase_functions_admin TO postgres;
+
+-- Remove unused supabase_pg_net_admin role
+DO
+$$
+BEGIN
+  IF EXISTS (
+    SELECT 1
+    FROM pg_roles
+    WHERE rolname = 'supabase_pg_net_admin'
+  )
+  THEN
+    REASSIGN OWNED BY supabase_pg_net_admin TO supabase_admin;
+    DROP OWNED BY supabase_pg_net_admin;
+    DROP ROLE supabase_pg_net_admin;
+  END IF;
+END
+$$;
+
+-- pg_net grants when extension is already enabled
+DO
+$$
+BEGIN
+  IF EXISTS (
+    SELECT 1
+    FROM pg_extension
+    WHERE extname = 'pg_net'
+  )
+  THEN
+    GRANT USAGE ON SCHEMA net TO supabase_functions_admin, postgres, anon, authenticated, service_role;
+
+    ALTER function net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) SECURITY DEFINER;
+    ALTER function net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) SECURITY DEFINER;
+
+    ALTER function net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) SET search_path = net;
+    ALTER function net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) SET search_path = net;
+
+    REVOKE ALL ON FUNCTION net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) FROM PUBLIC;
+    REVOKE ALL ON FUNCTION net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) FROM PUBLIC;
+
+    GRANT EXECUTE ON FUNCTION net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) TO supabase_functions_admin, postgres, anon, authenticated, service_role;
+    GRANT EXECUTE ON FUNCTION net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) TO supabase_functions_admin, postgres, anon, authenticated, service_role;
+  END IF;
+END
+$$;
+
+-- Event trigger for pg_net
+CREATE OR REPLACE FUNCTION extensions.grant_pg_net_access()
+RETURNS event_trigger
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  IF EXISTS (
+    SELECT 1
+    FROM pg_event_trigger_ddl_commands() AS ev
+    JOIN pg_extension AS ext
+    ON ev.objid = ext.oid
+    WHERE ext.extname = 'pg_net'
+  )
+  THEN
+    IF NOT EXISTS (
+      SELECT 1
+      FROM pg_roles
+      WHERE rolname = 'supabase_functions_admin'
+    )
+    THEN
+      CREATE USER supabase_functions_admin NOINHERIT CREATEROLE LOGIN NOREPLICATION;
+    END IF;
+
+    GRANT USAGE ON SCHEMA net TO supabase_functions_admin, postgres, anon, authenticated, service_role;
+
+    ALTER function net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) SECURITY DEFINER;
+    ALTER function net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) SECURITY DEFINER;
+
+    ALTER function net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) SET search_path = net;
+    ALTER function net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) SET search_path = net;
+
+    REVOKE ALL ON FUNCTION net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) FROM PUBLIC;
+    REVOKE ALL ON FUNCTION net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) FROM PUBLIC;
+
+    GRANT EXECUTE ON FUNCTION net.http_get(url text, params jsonb, headers jsonb, timeout_milliseconds integer) TO supabase_functions_admin, postgres, anon, authenticated, service_role;
+    GRANT EXECUTE ON FUNCTION net.http_post(url text, body jsonb, params jsonb, headers jsonb, timeout_milliseconds integer) TO supabase_functions_admin, postgres, anon, authenticated, service_role;
+  END IF;
+END;
+$$;
+COMMENT ON FUNCTION extensions.grant_pg_net_access IS 'Grants access to pg_net';
+
+DO
+$$
+BEGIN
+  IF NOT EXISTS (
+    SELECT 1
+    FROM pg_event_trigger
+    WHERE evtname = 'issue_pg_net_access'
+  ) THEN
+    CREATE EVENT TRIGGER issue_pg_net_access ON ddl_command_end WHEN TAG IN ('CREATE EXTENSION')
+    EXECUTE PROCEDURE extensions.grant_pg_net_access();
+  END IF;
+END
+$$;
+
+INSERT INTO supabase_functions.migrations (version) VALUES ('20210809183423_update_grants');
+
+ALTER function supabase_functions.http_request() SECURITY DEFINER;
+ALTER function supabase_functions.http_request() SET search_path = supabase_functions;
+REVOKE ALL ON FUNCTION supabase_functions.http_request() FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION supabase_functions.http_request() TO postgres, anon, authenticated, service_role;
+
+
+-- migrate:down
diff --git a/migrations/schema.sql b/migrations/schema.sql
index f68d131e8..d9b897e97 100644
--- a/migrations/schema.sql
+++ b/migrations/schema.sql
@@ -37,6 +37,20 @@ CREATE SCHEMA graphql;
 CREATE SCHEMA graphql_public;
 
 
+--
+-- Name: pg_net; Type: EXTENSION; Schema: -; Owner: -
+--
+
+CREATE EXTENSION IF NOT EXISTS pg_net WITH SCHEMA extensions;
+
+
+--
+-- Name: EXTENSION pg_net; Type: COMMENT; Schema: -; Owner: -
+--
+
+COMMENT ON EXTENSION pg_net IS 'Async HTTP';
+
+
 --
 -- Name: pgbouncer; Type: SCHEMA; Schema: -; Owner: -
 --
@@ -79,6 +93,13 @@ CREATE SCHEMA realtime;
 CREATE SCHEMA storage;
 
 
+--
+-- Name: supabase_functions; Type: SCHEMA; Schema: -; Owner: -
+--
+
+CREATE SCHEMA supabase_functions;
+
+
 --
 -- Name: vault; Type: SCHEMA; Schema: -; Owner: -
 --
@@ -574,6 +595,87 @@ END
 $$;
 
 
+--
+-- Name: http_request(); Type: FUNCTION; Schema: supabase_functions; Owner: -
+--
+
+CREATE FUNCTION supabase_functions.http_request() RETURNS trigger
+    LANGUAGE plpgsql SECURITY DEFINER
+    SET search_path TO 'supabase_functions'
+    AS $$
+  DECLARE
+    request_id bigint;
+    payload jsonb;
+    url text := TG_ARGV[0]::text;
+    method text := TG_ARGV[1]::text;
+    headers jsonb DEFAULT '{}'::jsonb;
+    params jsonb DEFAULT '{}'::jsonb;
+    timeout_ms integer DEFAULT 1000;
+  BEGIN
+    IF url IS NULL OR url = 'null' THEN
+      RAISE EXCEPTION 'url argument is missing';
+    END IF;
+
+    IF method IS NULL OR method = 'null' THEN
+      RAISE EXCEPTION 'method argument is missing';
+    END IF;
+
+    IF TG_ARGV[2] IS NULL OR TG_ARGV[2] = 'null' THEN
+      headers = '{"Content-Type": "application/json"}'::jsonb;
+    ELSE
+      headers = TG_ARGV[2]::jsonb;
+    END IF;
+
+    IF TG_ARGV[3] IS NULL OR TG_ARGV[3] = 'null' THEN
+      params = '{}'::jsonb;
+    ELSE
+      params = TG_ARGV[3]::jsonb;
+    END IF;
+
+    IF TG_ARGV[4] IS NULL OR TG_ARGV[4] = 'null' THEN
+      timeout_ms = 1000;
+    ELSE
+      timeout_ms = TG_ARGV[4]::integer;
+    END IF;
+
+    CASE
+      WHEN method = 'GET' THEN
+        SELECT http_get INTO request_id FROM net.http_get(
+          url,
+          params,
+          headers,
+          timeout_ms
+        );
+      WHEN method = 'POST' THEN
+        payload = jsonb_build_object(
+          'old_record', OLD,
+          'record', NEW,
+          'type', TG_OP,
+          'table', TG_TABLE_NAME,
+          'schema', TG_TABLE_SCHEMA
+        );
+
+        SELECT http_post INTO request_id FROM net.http_post(
+          url,
+          payload,
+          params,
+          headers,
+          timeout_ms
+        );
+      ELSE
+        RAISE EXCEPTION 'method argument % is invalid', method;
+    END CASE;
+
+    INSERT INTO supabase_functions.hooks
+      (hook_table_id, hook_name, request_id)
+    VALUES
+      (TG_RELID, TG_NAME, request_id);
+
+    RETURN NEW;
+  END
+$$;
+
+
 --
 -- Name: secrets_encrypt_secret_secret(); Type: FUNCTION; Schema: vault; Owner: -
 --
@@ -782,6 +884,55 @@ CREATE TABLE storage.objects (
 );
 
 
+--
+-- Name: hooks; Type: TABLE; Schema: supabase_functions; Owner: -
+--
+
+CREATE TABLE supabase_functions.hooks (
+    id bigint NOT NULL,
+    hook_table_id integer NOT NULL,
+    hook_name text NOT NULL,
+    created_at timestamp with time zone DEFAULT now() NOT NULL,
+    request_id bigint
+);
+
+
+--
+-- Name: TABLE hooks; Type: COMMENT; Schema: supabase_functions; Owner: -
+--
+
+COMMENT ON TABLE supabase_functions.hooks IS 'Supabase Functions Hooks: Audit trail for triggered hooks.';
+
+
+--
+-- Name: hooks_id_seq; Type: SEQUENCE; Schema: supabase_functions; Owner: -
+--
+
+CREATE SEQUENCE supabase_functions.hooks_id_seq
+    START WITH 1
+    INCREMENT BY 1
+    NO MINVALUE
+    NO MAXVALUE
+    CACHE 1;
+
+
+--
+-- Name: hooks_id_seq; Type: SEQUENCE OWNED BY; Schema: supabase_functions; Owner: -
+--
+
+ALTER SEQUENCE supabase_functions.hooks_id_seq OWNED BY supabase_functions.hooks.id;
+
+
+--
+-- Name: migrations; Type: TABLE; Schema: supabase_functions; Owner: -
+--
+
+CREATE TABLE supabase_functions.migrations (
+    version text NOT NULL,
+    inserted_at timestamp with time zone DEFAULT now() NOT NULL
+);
+
+
 --
 -- Name: decrypted_secrets; Type: VIEW; Schema: vault; Owner: -
 --
@@ -813,6 +964,13 @@ CREATE VIEW vault.decrypted_secrets AS
 ALTER TABLE ONLY auth.refresh_tokens ALTER COLUMN id SET DEFAULT nextval('auth.refresh_tokens_id_seq'::regclass);
 
 
+--
+-- Name: hooks id; Type: DEFAULT; Schema: supabase_functions; Owner: -
+--
+
+ALTER TABLE ONLY supabase_functions.hooks ALTER COLUMN id SET DEFAULT nextval('supabase_functions.hooks_id_seq'::regclass);
+
+
 --
 -- Name: audit_log_entries audit_log_entries_pkey; Type: CONSTRAINT; Schema: auth; Owner: -
 --
@@ -901,6 +1059,22 @@ ALTER TABLE ONLY storage.objects
     ADD CONSTRAINT objects_pkey PRIMARY KEY (id);
 
 
+--
+-- Name: hooks hooks_pkey; Type: CONSTRAINT; Schema: supabase_functions; Owner: -
+--
+
+ALTER TABLE ONLY supabase_functions.hooks
+    ADD CONSTRAINT hooks_pkey PRIMARY KEY (id);
+
+
+--
+-- Name: migrations migrations_pkey; Type: CONSTRAINT; Schema: supabase_functions; Owner: -
+--
+
+ALTER TABLE ONLY supabase_functions.migrations
+    ADD CONSTRAINT migrations_pkey PRIMARY KEY (version);
+
+
 --
 -- Name: audit_logs_instance_id_idx; Type: INDEX; Schema: auth; Owner: -
 --
@@ -964,6 +1138,20 @@ CREATE UNIQUE INDEX bucketid_objname ON storage.objects USING btree (bucket_id,
 CREATE INDEX name_prefix_search ON storage.objects USING btree (name text_pattern_ops);
 
 
+--
+-- Name: supabase_functions_hooks_h_table_id_h_name_idx; Type: INDEX; Schema: supabase_functions; Owner: -
+--
+
+CREATE INDEX supabase_functions_hooks_h_table_id_h_name_idx ON supabase_functions.hooks USING btree (hook_table_id, hook_name);
+
+
+--
+-- Name: supabase_functions_hooks_request_id_idx; Type: INDEX; Schema: supabase_functions; Owner: -
+--
+
+CREATE INDEX supabase_functions_hooks_request_id_idx ON supabase_functions.hooks USING btree (request_id);
+
+
 --
 -- Name: buckets buckets_owner_fkey; Type: FK CONSTRAINT; Schema: storage; Owner: -
 --

From e6c0474e2a8dcf97a952e9d4cd3cc0bdb02fab8e Mon Sep 17 00:00:00 2001
From: Qiao Han <qiao@supabase.io>
Date: Thu, 22 Aug 2024 02:35:23 +0800
Subject: [PATCH 2/5] feat: support webhook retries

---
 ...40822021428_enable_webhooks_by_default.sql | 126 +++++++++++-------
 migrations/schema.sql                         | 104 +++++++++------
 2 files changed, 141 insertions(+), 89 deletions(-)

diff --git a/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql b/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
index 1d5746437..c83137f37 100644
--- a/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
+++ b/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
@@ -4,7 +4,7 @@
 CREATE EXTENSION IF NOT EXISTS pg_net SCHEMA extensions;
 
 -- Create supabase_functions schema
-CREATE SCHEMA supabase_functions AUTHORIZATION supabase_admin;
+CREATE SCHEMA IF NOT EXISTS supabase_functions AUTHORIZATION supabase_admin;
 
 GRANT USAGE ON SCHEMA supabase_functions TO postgres, anon, authenticated, service_role;
 ALTER DEFAULT PRIVILEGES IN SCHEMA supabase_functions GRANT ALL ON TABLES TO postgres, anon, authenticated, service_role;
@@ -12,98 +12,128 @@ ALTER DEFAULT PRIVILEGES IN SCHEMA supabase_functions GRANT ALL ON FUNCTIONS TO
 ALTER DEFAULT PRIVILEGES IN SCHEMA supabase_functions GRANT ALL ON SEQUENCES TO postgres, anon, authenticated, service_role;
 
 -- supabase_functions.migrations definition
-CREATE TABLE supabase_functions.migrations (
+CREATE TABLE IF NOT EXISTS supabase_functions.migrations (
   version text PRIMARY KEY,
   inserted_at timestamptz NOT NULL DEFAULT NOW()
 );
 
 -- Initial supabase_functions migration
-INSERT INTO supabase_functions.migrations (version) VALUES ('initial');
+INSERT INTO supabase_functions.migrations (version) VALUES
+  ('initial'),
+  ('20210809183423_update_grants'),
+  ('20240125163000_add_retry_to_http_request')
+ON CONFLICT DO NOTHING;
 
 -- supabase_functions.hooks definition
-CREATE TABLE supabase_functions.hooks (
+CREATE TABLE IF NOT EXISTS supabase_functions.hooks (
   id bigserial PRIMARY KEY,
   hook_table_id integer NOT NULL,
   hook_name text NOT NULL,
   created_at timestamptz NOT NULL DEFAULT NOW(),
   request_id bigint
 );
-CREATE INDEX supabase_functions_hooks_request_id_idx ON supabase_functions.hooks USING btree (request_id);
-CREATE INDEX supabase_functions_hooks_h_table_id_h_name_idx ON supabase_functions.hooks USING btree (hook_table_id, hook_name);
+CREATE INDEX IF NOT EXISTS supabase_functions_hooks_request_id_idx ON supabase_functions.hooks USING btree (request_id);
+CREATE INDEX IF NOT EXISTS supabase_functions_hooks_h_table_id_h_name_idx ON supabase_functions.hooks USING btree (hook_table_id, hook_name);
 COMMENT ON TABLE supabase_functions.hooks IS 'Supabase Functions Hooks: Audit trail for triggered hooks.';
 
-CREATE FUNCTION supabase_functions.http_request()
+CREATE OR REPLACE FUNCTION supabase_functions.http_request()
   RETURNS trigger
   LANGUAGE plpgsql
+  SECURITY DEFINER
+  SET search_path TO 'supabase_functions'
   AS $function$
   DECLARE
-    request_id bigint;
+    local_request_id bigint;
     payload jsonb;
     url text := TG_ARGV[0]::text;
     method text := TG_ARGV[1]::text;
     headers jsonb DEFAULT '{}'::jsonb;
     params jsonb DEFAULT '{}'::jsonb;
-    timeout_ms integer DEFAULT 1000;
+    timeout_ms integer;
+    retry_count integer DEFAULT 0;
+    max_retries integer := COALESCE(TG_ARGV[5]::integer, 0);
+    succeeded boolean := FALSE;
+    retry_delays double precision[] := ARRAY[0, 0.250, 0.500, 1.000, 2.500, 5.000];
+    status_code integer := 0;
   BEGIN
     IF url IS NULL OR url = 'null' THEN
       RAISE EXCEPTION 'url argument is missing';
     END IF;
-
     IF method IS NULL OR method = 'null' THEN
       RAISE EXCEPTION 'method argument is missing';
     END IF;
-
     IF TG_ARGV[2] IS NULL OR TG_ARGV[2] = 'null' THEN
       headers = '{"Content-Type": "application/json"}'::jsonb;
     ELSE
       headers = TG_ARGV[2]::jsonb;
     END IF;
-
     IF TG_ARGV[3] IS NULL OR TG_ARGV[3] = 'null' THEN
       params = '{}'::jsonb;
     ELSE
       params = TG_ARGV[3]::jsonb;
     END IF;
-
-    IF TG_ARGV[4] IS NULL OR TG_ARGV[4] = 'null' THEN
-      timeout_ms = 1000;
-    ELSE
+    IF TG_ARGV[4] IS NOT NULL OR TG_ARGV[4] <> 'null' THEN
       timeout_ms = TG_ARGV[4]::integer;
     END IF;
-
-    CASE
-      WHEN method = 'GET' THEN
-        SELECT http_get INTO request_id FROM net.http_get(
-          url,
-          params,
-          headers,
-          timeout_ms
-        );
-      WHEN method = 'POST' THEN
-        payload = jsonb_build_object(
-          'old_record', OLD,
-          'record', NEW,
-          'type', TG_OP,
-          'table', TG_TABLE_NAME,
-          'schema', TG_TABLE_SCHEMA
-        );
-
-        SELECT http_post INTO request_id FROM net.http_post(
-          url,
-          payload,
-          params,
-          headers,
-          timeout_ms
-        );
-      ELSE
-        RAISE EXCEPTION 'method argument % is invalid', method;
-    END CASE;
-
+    -- Retry loop
+    WHILE NOT succeeded AND retry_count <= max_retries LOOP
+      PERFORM pg_sleep(retry_delays[retry_count + 1]);
+      IF retry_delays[retry_count + 1] > 0 THEN
+        RAISE WARNING 'Retrying HTTP request: {retry_attempt: %, url: "%", timeout_ms: %, retry_delay_ms: %}',
+          retry_count, url, timeout_ms, retry_delays[retry_count + 1] * 1000;
+      END IF;
+      retry_count := retry_count + 1;
+      BEGIN
+        CASE
+          WHEN method = 'GET' THEN
+            SELECT http_get INTO local_request_id FROM net.http_get(
+              url,
+              params,
+              headers,
+              timeout_ms
+            );
+          WHEN method = 'POST' THEN
+            payload = jsonb_build_object(
+              'old_record', OLD,
+              'record', NEW,
+              'type', TG_OP,
+              'table', TG_TABLE_NAME,
+              'schema', TG_TABLE_SCHEMA
+            );
+            SELECT http_post INTO local_request_id FROM net.http_post(
+              url,
+              payload,
+              params,
+              headers,
+              timeout_ms
+            );
+          ELSE
+            RAISE EXCEPTION 'method argument % is invalid', method;
+        END CASE;
+        IF local_request_id IS NOT NULL THEN
+          SELECT (response).status_code::integer
+            INTO status_code
+            FROM net._http_collect_response(local_request_id);
+          IF status_code < 500 THEN
+            succeeded := TRUE;
+          END IF;
+        END IF;
+        -- Exit loop on successful request
+        EXIT WHEN succeeded;
+      EXCEPTION
+        WHEN OTHERS THEN
+          IF retry_count > max_retries THEN
+            -- If retries exhausted, re-raise exception
+            RAISE EXCEPTION 'HTTP request failed after % retries. SQL Error: { %, % }',
+              max_retries, SQLERRM, SQLSTATE;
+          END IF;
+      END;
+    END LOOP;
+    -- Failed retries are not logged
     INSERT INTO supabase_functions.hooks
       (hook_table_id, hook_name, request_id)
     VALUES
-      (TG_RELID, TG_NAME, request_id);
-
+      (TG_RELID, TG_NAME, local_request_id);
     RETURN NEW;
   END
 $function$;
@@ -231,8 +261,6 @@ BEGIN
 END
 $$;
 
-INSERT INTO supabase_functions.migrations (version) VALUES ('20210809183423_update_grants');
-
 ALTER function supabase_functions.http_request() SECURITY DEFINER;
 ALTER function supabase_functions.http_request() SET search_path = supabase_functions;
 REVOKE ALL ON FUNCTION supabase_functions.http_request() FROM PUBLIC;
diff --git a/migrations/schema.sql b/migrations/schema.sql
index d9b897e97..1f0743f9c 100644
--- a/migrations/schema.sql
+++ b/migrations/schema.sql
@@ -604,73 +604,97 @@ CREATE FUNCTION supabase_functions.http_request() RETURNS trigger
     SET search_path TO 'supabase_functions'
     AS $$
   DECLARE
-    request_id bigint;
+    local_request_id bigint;
     payload jsonb;
     url text := TG_ARGV[0]::text;
     method text := TG_ARGV[1]::text;
     headers jsonb DEFAULT '{}'::jsonb;
     params jsonb DEFAULT '{}'::jsonb;
-    timeout_ms integer DEFAULT 1000;
+    timeout_ms integer;
+    retry_count integer DEFAULT 0;
+    max_retries integer := COALESCE(TG_ARGV[5]::integer, 0);
+    succeeded boolean := FALSE;
+    retry_delays double precision[] := ARRAY[0, 0.250, 0.500, 1.000, 2.500, 5.000];
+    status_code integer := 0;
   BEGIN
     IF url IS NULL OR url = 'null' THEN
       RAISE EXCEPTION 'url argument is missing';
     END IF;
-
     IF method IS NULL OR method = 'null' THEN
       RAISE EXCEPTION 'method argument is missing';
     END IF;
-
     IF TG_ARGV[2] IS NULL OR TG_ARGV[2] = 'null' THEN
       headers = '{"Content-Type": "application/json"}'::jsonb;
     ELSE
       headers = TG_ARGV[2]::jsonb;
     END IF;
-
     IF TG_ARGV[3] IS NULL OR TG_ARGV[3] = 'null' THEN
       params = '{}'::jsonb;
     ELSE
       params = TG_ARGV[3]::jsonb;
     END IF;
-
-    IF TG_ARGV[4] IS NULL OR TG_ARGV[4] = 'null' THEN
-      timeout_ms = 1000;
-    ELSE
+    IF TG_ARGV[4] IS NOT NULL OR TG_ARGV[4] <> 'null' THEN
       timeout_ms = TG_ARGV[4]::integer;
     END IF;
-
-    CASE
-      WHEN method = 'GET' THEN
-        SELECT http_get INTO request_id FROM net.http_get(
-          url,
-          params,
-          headers,
-          timeout_ms
-        );
-      WHEN method = 'POST' THEN
-        payload = jsonb_build_object(
-          'old_record', OLD,
-          'record', NEW,
-          'type', TG_OP,
-          'table', TG_TABLE_NAME,
-          'schema', TG_TABLE_SCHEMA
-        );
-
-        SELECT http_post INTO request_id FROM net.http_post(
-          url,
-          payload,
-          params,
-          headers,
-          timeout_ms
-        );
-      ELSE
-        RAISE EXCEPTION 'method argument % is invalid', method;
-    END CASE;
-
+    -- Retry loop
+    WHILE NOT succeeded AND retry_count <= max_retries LOOP
+      PERFORM pg_sleep(retry_delays[retry_count + 1]);
+      IF retry_delays[retry_count + 1] > 0 THEN
+        RAISE WARNING 'Retrying HTTP request: {retry_attempt: %, url: "%", timeout_ms: %, retry_delay_ms: %}',
+          retry_count, url, timeout_ms, retry_delays[retry_count + 1] * 1000;
+      END IF;
+      retry_count := retry_count + 1;
+      BEGIN
+        CASE
+          WHEN method = 'GET' THEN
+            SELECT http_get INTO local_request_id FROM net.http_get(
+              url,
+              params,
+              headers,
+              timeout_ms
+            );
+          WHEN method = 'POST' THEN
+            payload = jsonb_build_object(
+              'old_record', OLD,
+              'record', NEW,
+              'type', TG_OP,
+              'table', TG_TABLE_NAME,
+              'schema', TG_TABLE_SCHEMA
+            );
+            SELECT http_post INTO local_request_id FROM net.http_post(
+              url,
+              payload,
+              params,
+              headers,
+              timeout_ms
+            );
+          ELSE
+            RAISE EXCEPTION 'method argument % is invalid', method;
+        END CASE;
+        IF local_request_id IS NOT NULL THEN
+          SELECT (response).status_code::integer
+            INTO status_code
+            FROM net._http_collect_response(local_request_id);
+          IF status_code < 500 THEN
+            succeeded := TRUE;
+          END IF;
+        END IF;
+        -- Exit loop on successful request
+        EXIT WHEN succeeded;
+      EXCEPTION
+        WHEN OTHERS THEN
+          IF retry_count > max_retries THEN
+            -- If retries exhausted, re-raise exception
+            RAISE EXCEPTION 'HTTP request failed after % retries. SQL Error: { %, % }',
+              max_retries, SQLERRM, SQLSTATE;
+          END IF;
+      END;
+    END LOOP;
+    -- Failed retries are not logged
     INSERT INTO supabase_functions.hooks
       (hook_table_id, hook_name, request_id)
     VALUES
-      (TG_RELID, TG_NAME, request_id);
-
+      (TG_RELID, TG_NAME, local_request_id);
     RETURN NEW;
   END
 $$;

From 4bb977b68380cd30d9822737a20042b4145b5134 Mon Sep 17 00:00:00 2001
From: Qiao Han <qiao@supabase.io>
Date: Thu, 22 Aug 2024 14:20:22 +0800
Subject: [PATCH 3/5] chore: remove retry logic

---
 ...40822021428_enable_webhooks_by_default.sql | 109 +++++++-----------
 migrations/schema.sql                         | 104 +++++++----------
 2 files changed, 81 insertions(+), 132 deletions(-)

diff --git a/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql b/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
index c83137f37..579a10cbf 100644
--- a/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
+++ b/migrations/db/migrations/20240822021428_enable_webhooks_by_default.sql
@@ -20,8 +20,7 @@ CREATE TABLE IF NOT EXISTS supabase_functions.migrations (
 -- Initial supabase_functions migration
 INSERT INTO supabase_functions.migrations (version) VALUES
   ('initial'),
-  ('20210809183423_update_grants'),
-  ('20240125163000_add_retry_to_http_request')
+  ('20210809183423_update_grants')
 ON CONFLICT DO NOTHING;
 
 -- supabase_functions.hooks definition
@@ -39,101 +38,75 @@ COMMENT ON TABLE supabase_functions.hooks IS 'Supabase Functions Hooks: Audit tr
 CREATE OR REPLACE FUNCTION supabase_functions.http_request()
   RETURNS trigger
   LANGUAGE plpgsql
-  SECURITY DEFINER
-  SET search_path TO 'supabase_functions'
   AS $function$
   DECLARE
-    local_request_id bigint;
+    request_id bigint;
     payload jsonb;
     url text := TG_ARGV[0]::text;
     method text := TG_ARGV[1]::text;
     headers jsonb DEFAULT '{}'::jsonb;
     params jsonb DEFAULT '{}'::jsonb;
-    timeout_ms integer;
-    retry_count integer DEFAULT 0;
-    max_retries integer := COALESCE(TG_ARGV[5]::integer, 0);
-    succeeded boolean := FALSE;
-    retry_delays double precision[] := ARRAY[0, 0.250, 0.500, 1.000, 2.500, 5.000];
-    status_code integer := 0;
+    timeout_ms integer DEFAULT 1000;
   BEGIN
     IF url IS NULL OR url = 'null' THEN
       RAISE EXCEPTION 'url argument is missing';
     END IF;
+
     IF method IS NULL OR method = 'null' THEN
       RAISE EXCEPTION 'method argument is missing';
     END IF;
+
     IF TG_ARGV[2] IS NULL OR TG_ARGV[2] = 'null' THEN
       headers = '{"Content-Type": "application/json"}'::jsonb;
     ELSE
       headers = TG_ARGV[2]::jsonb;
     END IF;
+
     IF TG_ARGV[3] IS NULL OR TG_ARGV[3] = 'null' THEN
       params = '{}'::jsonb;
     ELSE
       params = TG_ARGV[3]::jsonb;
     END IF;
-    IF TG_ARGV[4] IS NOT NULL OR TG_ARGV[4] <> 'null' THEN
+
+    IF TG_ARGV[4] IS NULL OR TG_ARGV[4] = 'null' THEN
+      timeout_ms = 1000;
+    ELSE
       timeout_ms = TG_ARGV[4]::integer;
     END IF;
-    -- Retry loop
-    WHILE NOT succeeded AND retry_count <= max_retries LOOP
-      PERFORM pg_sleep(retry_delays[retry_count + 1]);
-      IF retry_delays[retry_count + 1] > 0 THEN
-        RAISE WARNING 'Retrying HTTP request: {retry_attempt: %, url: "%", timeout_ms: %, retry_delay_ms: %}',
-          retry_count, url, timeout_ms, retry_delays[retry_count + 1] * 1000;
-      END IF;
-      retry_count := retry_count + 1;
-      BEGIN
-        CASE
-          WHEN method = 'GET' THEN
-            SELECT http_get INTO local_request_id FROM net.http_get(
-              url,
-              params,
-              headers,
-              timeout_ms
-            );
-          WHEN method = 'POST' THEN
-            payload = jsonb_build_object(
-              'old_record', OLD,
-              'record', NEW,
-              'type', TG_OP,
-              'table', TG_TABLE_NAME,
-              'schema', TG_TABLE_SCHEMA
-            );
-            SELECT http_post INTO local_request_id FROM net.http_post(
-              url,
-              payload,
-              params,
-              headers,
-              timeout_ms
-            );
-          ELSE
-            RAISE EXCEPTION 'method argument % is invalid', method;
-        END CASE;
-        IF local_request_id IS NOT NULL THEN
-          SELECT (response).status_code::integer
-            INTO status_code
-            FROM net._http_collect_response(local_request_id);
-          IF status_code < 500 THEN
-            succeeded := TRUE;
-          END IF;
-        END IF;
-        -- Exit loop on successful request
-        EXIT WHEN succeeded;
-      EXCEPTION
-        WHEN OTHERS THEN
-          IF retry_count > max_retries THEN
-            -- If retries exhausted, re-raise exception
-            RAISE EXCEPTION 'HTTP request failed after % retries. SQL Error: { %, % }',
-              max_retries, SQLERRM, SQLSTATE;
-          END IF;
-      END;
-    END LOOP;
-    -- Failed retries are not logged
+
+    CASE
+      WHEN method = 'GET' THEN
+        SELECT http_get INTO request_id FROM net.http_get(
+          url,
+          params,
+          headers,
+          timeout_ms
+        );
+      WHEN method = 'POST' THEN
+        payload = jsonb_build_object(
+          'old_record', OLD,
+          'record', NEW,
+          'type', TG_OP,
+          'table', TG_TABLE_NAME,
+          'schema', TG_TABLE_SCHEMA
+        );
+
+        SELECT http_post INTO request_id FROM net.http_post(
+          url,
+          payload,
+          params,
+          headers,
+          timeout_ms
+        );
+      ELSE
+        RAISE EXCEPTION 'method argument % is invalid', method;
+    END CASE;
+
     INSERT INTO supabase_functions.hooks
       (hook_table_id, hook_name, request_id)
     VALUES
-      (TG_RELID, TG_NAME, local_request_id);
+      (TG_RELID, TG_NAME, request_id);
+
     RETURN NEW;
   END
 $function$;
diff --git a/migrations/schema.sql b/migrations/schema.sql
index 1f0743f9c..d9b897e97 100644
--- a/migrations/schema.sql
+++ b/migrations/schema.sql
@@ -604,97 +604,73 @@ CREATE FUNCTION supabase_functions.http_request() RETURNS trigger
     SET search_path TO 'supabase_functions'
     AS $$
   DECLARE
-    local_request_id bigint;
+    request_id bigint;
     payload jsonb;
     url text := TG_ARGV[0]::text;
     method text := TG_ARGV[1]::text;
     headers jsonb DEFAULT '{}'::jsonb;
     params jsonb DEFAULT '{}'::jsonb;
-    timeout_ms integer;
-    retry_count integer DEFAULT 0;
-    max_retries integer := COALESCE(TG_ARGV[5]::integer, 0);
-    succeeded boolean := FALSE;
-    retry_delays double precision[] := ARRAY[0, 0.250, 0.500, 1.000, 2.500, 5.000];
-    status_code integer := 0;
+    timeout_ms integer DEFAULT 1000;
   BEGIN
     IF url IS NULL OR url = 'null' THEN
       RAISE EXCEPTION 'url argument is missing';
     END IF;
+
     IF method IS NULL OR method = 'null' THEN
       RAISE EXCEPTION 'method argument is missing';
     END IF;
+
     IF TG_ARGV[2] IS NULL OR TG_ARGV[2] = 'null' THEN
       headers = '{"Content-Type": "application/json"}'::jsonb;
     ELSE
       headers = TG_ARGV[2]::jsonb;
     END IF;
+
     IF TG_ARGV[3] IS NULL OR TG_ARGV[3] = 'null' THEN
       params = '{}'::jsonb;
     ELSE
       params = TG_ARGV[3]::jsonb;
     END IF;
-    IF TG_ARGV[4] IS NOT NULL OR TG_ARGV[4] <> 'null' THEN
+
+    IF TG_ARGV[4] IS NULL OR TG_ARGV[4] = 'null' THEN
+      timeout_ms = 1000;
+    ELSE
       timeout_ms = TG_ARGV[4]::integer;
     END IF;
-    -- Retry loop
-    WHILE NOT succeeded AND retry_count <= max_retries LOOP
-      PERFORM pg_sleep(retry_delays[retry_count + 1]);
-      IF retry_delays[retry_count + 1] > 0 THEN
-        RAISE WARNING 'Retrying HTTP request: {retry_attempt: %, url: "%", timeout_ms: %, retry_delay_ms: %}',
-          retry_count, url, timeout_ms, retry_delays[retry_count + 1] * 1000;
-      END IF;
-      retry_count := retry_count + 1;
-      BEGIN
-        CASE
-          WHEN method = 'GET' THEN
-            SELECT http_get INTO local_request_id FROM net.http_get(
-              url,
-              params,
-              headers,
-              timeout_ms
-            );
-          WHEN method = 'POST' THEN
-            payload = jsonb_build_object(
-              'old_record', OLD,
-              'record', NEW,
-              'type', TG_OP,
-              'table', TG_TABLE_NAME,
-              'schema', TG_TABLE_SCHEMA
-            );
-            SELECT http_post INTO local_request_id FROM net.http_post(
-              url,
-              payload,
-              params,
-              headers,
-              timeout_ms
-            );
-          ELSE
-            RAISE EXCEPTION 'method argument % is invalid', method;
-        END CASE;
-        IF local_request_id IS NOT NULL THEN
-          SELECT (response).status_code::integer
-            INTO status_code
-            FROM net._http_collect_response(local_request_id);
-          IF status_code < 500 THEN
-            succeeded := TRUE;
-          END IF;
-        END IF;
-        -- Exit loop on successful request
-        EXIT WHEN succeeded;
-      EXCEPTION
-        WHEN OTHERS THEN
-          IF retry_count > max_retries THEN
-            -- If retries exhausted, re-raise exception
-            RAISE EXCEPTION 'HTTP request failed after % retries. SQL Error: { %, % }',
-              max_retries, SQLERRM, SQLSTATE;
-          END IF;
-      END;
-    END LOOP;
-    -- Failed retries are not logged
+
+    CASE
+      WHEN method = 'GET' THEN
+        SELECT http_get INTO request_id FROM net.http_get(
+          url,
+          params,
+          headers,
+          timeout_ms
+        );
+      WHEN method = 'POST' THEN
+        payload = jsonb_build_object(
+          'old_record', OLD,
+          'record', NEW,
+          'type', TG_OP,
+          'table', TG_TABLE_NAME,
+          'schema', TG_TABLE_SCHEMA
+        );
+
+        SELECT http_post INTO request_id FROM net.http_post(
+          url,
+          payload,
+          params,
+          headers,
+          timeout_ms
+        );
+      ELSE
+        RAISE EXCEPTION 'method argument % is invalid', method;
+    END CASE;
+
     INSERT INTO supabase_functions.hooks
       (hook_table_id, hook_name, request_id)
     VALUES
-      (TG_RELID, TG_NAME, local_request_id);
+      (TG_RELID, TG_NAME, request_id);
+
     RETURN NEW;
   END
 $$;

From 24afeb13d191e2d0cae4a38b04ba5d1d1acac616 Mon Sep 17 00:00:00 2001
From: Qiao Han <qiao@supabase.io>
Date: Thu, 22 Aug 2024 13:42:33 +0800
Subject: [PATCH 4/5] chore: include pg_net in shared preload libraries

---
 ansible/tasks/setup-postgres.yml | 2 +-
 1 file changed, 1 insertion(+), 1 deletion(-)

diff --git a/ansible/tasks/setup-postgres.yml b/ansible/tasks/setup-postgres.yml
index c1cf1983e..85cb48d37 100644
--- a/ansible/tasks/setup-postgres.yml
+++ b/ansible/tasks/setup-postgres.yml
@@ -239,7 +239,7 @@
   become_user: postgres
   shell: |
     source /var/lib/postgresql/.bashrc
-    /usr/lib/postgresql/bin/pg_ctl -D /var/lib/postgresql/data start
+    /usr/lib/postgresql/bin/pg_ctl -D /var/lib/postgresql/data start -o "-c shared_preload_libraries='pg_net'"
   environment:
     LANG: en_US.UTF-8
     LANGUAGE: en_US.UTF-8

From 1685528b4c34ebc566e125e2ea10ce93fff4ea10 Mon Sep 17 00:00:00 2001
From: Qiao Han <qiao@supabase.io>
Date: Thu, 22 Aug 2024 16:12:48 +0800
Subject: [PATCH 5/5] chore: update extensions unit test

---
 ebssurrogate/files/unit-tests/unit-test-01.sql | 1 +
 1 file changed, 1 insertion(+)

diff --git a/ebssurrogate/files/unit-tests/unit-test-01.sql b/ebssurrogate/files/unit-tests/unit-test-01.sql
index 0feb70e8b..20226595f 100644
--- a/ebssurrogate/files/unit-tests/unit-test-01.sql
+++ b/ebssurrogate/files/unit-tests/unit-test-01.sql
@@ -12,6 +12,7 @@ SELECT extensions_are(
     'pg_graphql',
     'pgcrypto',
     'pgjwt',
+    'pg_net',
     'uuid-ossp',
     'supabase_vault'
      ]