├── .editorconfig ├── .github └── workflows │ └── ci.yml ├── .gitignore ├── LICENSE.md ├── META.json ├── Makefile ├── README.md ├── ci └── pg_hba.conf ├── examples └── s3.sql ├── expected └── http.out ├── http--1.0--1.1.sql ├── http--1.1--1.2.sql ├── http--1.2--1.3.sql ├── http--1.3--1.4.sql ├── http--1.4--1.5.sql ├── http--1.5--1.6.sql ├── http--1.6--1.7.sql ├── http--1.7.sql ├── http.c ├── http.control └── sql └── http.sql /.editorconfig: -------------------------------------------------------------------------------- 1 | # http://editorconfig.org 2 | 3 | # top-most EditorConfig file 4 | root = true 5 | 6 | # these are the defaults 7 | [*] 8 | charset = utf-8 9 | end_of_line = lf 10 | trim_trailing_whitespace = true 11 | insert_final_newline = true 12 | 13 | # C files want tab indentation 14 | [*.{c,h}] 15 | indent_style = tab 16 | 17 | # YAML files want space indentation 18 | [*.{yml}] 19 | indent_style = space 20 | indent_size = 4 21 | 22 | -------------------------------------------------------------------------------- /.github/workflows/ci.yml: -------------------------------------------------------------------------------- 1 | # GitHub Actions for PostGIS 2 | # 3 | # Paul Ramsey 4 | 5 | name: "CI" 6 | on: [push, pull_request] 7 | 8 | jobs: 9 | linux: 10 | 11 | runs-on: ubuntu-latest 12 | 13 | name: "CI" 14 | strategy: 15 | fail-fast: true 16 | matrix: 17 | ci: 18 | - { PGVER: 13 } 19 | - { PGVER: 14 } 20 | - { PGVER: 15 } 21 | - { PGVER: 16 } 22 | - { PGVER: 17 } 23 | - { PGVER: 18 } 24 | 25 | steps: 26 | 27 | - name: 'Check Out' 28 | uses: actions/checkout@v4 29 | 30 | - name: 'Raise Priority for apt.postgresql.org' 31 | run: | 32 | cat << EOF >> ./pgdg.pref 33 | Package: * 34 | Pin: release o=apt.postgresql.org 35 | Pin-Priority: 600 36 | EOF 37 | sudo mv ./pgdg.pref /etc/apt/preferences.d/ 38 | sudo apt update 39 | 40 | - name: 'Install PostgreSQL' 41 | run: | 42 | sudo apt-get purge postgresql-* 43 | sudo sh -c 'echo "deb http://apt.postgresql.org/pub/repos/apt $(lsb_release -cs)-pgdg-snapshot main ${{ matrix.ci.PGVER }}" > /etc/apt/sources.list.d/pgdg.list' 44 | curl https://www.postgresql.org/media/keys/ACCC4CF8.asc | gpg --dearmor | sudo tee /etc/apt/trusted.gpg.d/apt.postgresql.org.gpg >/dev/null 45 | sudo apt-get update 46 | sudo apt-get -y install postgresql-${{ matrix.ci.PGVER }} postgresql-server-dev-${{ matrix.ci.PGVER }} postgresql-client-${{ matrix.ci.PGVER }} 47 | 48 | - name: 'Install Curl' 49 | run: | 50 | sudo apt-get -y install libcurl4-gnutls-dev 51 | 52 | - name: 'Start PostgreSQL' 53 | run: | 54 | export PGVER=${{ matrix.ci.PGVER }} 55 | export PGDATA=/var/lib/postgresql/$PGVER/main 56 | export PGETC=/etc/postgresql/$PGVER/main 57 | export PGBIN=/usr/lib/postgresql/$PGVER/bin 58 | sudo chmod -R 755 /home/`whoami` 59 | sudo cp ./ci/pg_hba.conf $PGETC/pg_hba.conf 60 | sudo systemctl stop postgresql 61 | sudo pg_ctlcluster $PGVER main start 62 | sudo pg_lsclusters 63 | 64 | - name: 'Start HttpBin Docker' 65 | run: | 66 | docker run -d -p 9080:80 kennethreitz/httpbin 67 | 68 | - name: 'Build & Test' 69 | run: | 70 | export PATH=/usr/lib/postgresql/${{ matrix.ci.PGVER }}/bin/:$PATH 71 | export PG_CONFIG=/usr/lib/postgresql/${{ matrix.ci.PGVER }}/bin/pg_config 72 | export PG_CFLAGS=-Werror 73 | make 74 | sudo -E make PG_CONFIG=$PG_CONFIG install 75 | PGUSER=postgres make installcheck || (cat regression.diffs && /bin/false) 76 | 77 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | *.o 2 | *.so 3 | *.a 4 | *.pc 5 | *.dylib 6 | *.dll 7 | regression.diffs 8 | regression.out 9 | results/ 10 | tmp_check/ 11 | tmp_check_iso/ 12 | output_iso/ 13 | log/ 14 | -------------------------------------------------------------------------------- /LICENSE.md: -------------------------------------------------------------------------------- 1 | Copyright (C) 2025 Paul Ramsey 2 | 3 | Permission is hereby granted, free of charge, to any person obtaining a copy of this software and associated documentation files (the "Software"), to deal in the Software without restriction, including without limitation the rights to use, copy, modify, merge, publish, distribute, sublicense, and/or sell copies of the Software, and to permit persons to whom the Software is furnished to do so, subject to the following conditions: 4 | 5 | The above copyright notice and this permission notice shall be included in all copies or substantial portions of the Software. 6 | 7 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 8 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "http", 3 | "abstract": "HTTP client for PostgreSQL", 4 | "description": "HTTP allows you to get the content of a web page in a SQL function call.", 5 | "version": "1.7.0", 6 | "maintainer": [ 7 | "Paul Ramsey " 8 | ], 9 | "license": { 10 | "mit": "http://en.wikipedia.org/wiki/MIT_License" 11 | }, 12 | "prereqs": { 13 | "runtime": { 14 | "requires": { 15 | "PostgreSQL": "9.1.0" 16 | }, 17 | "recommends": { 18 | "PostgreSQL": "9.1.3" 19 | } 20 | } 21 | }, 22 | "provides": { 23 | "http": { 24 | "file": "http--1.7.sql", 25 | "docfile": "README.md", 26 | "version": "1.7.0", 27 | "abstract": "HTTP client for PostgreSQL" 28 | } 29 | }, 30 | "resources": { 31 | "homepage": "https://github.com/pramsey/pgsql-http/", 32 | "bugtracker": { 33 | "web": "https://github.com/pramsey/pgsql-http/issues" 34 | }, 35 | "repository": { 36 | "url": "https://github.com/pramsey/pgsql-http.git", 37 | "web": "https://github.com/pramsey/pgsql-http/", 38 | "type": "git" 39 | } 40 | }, 41 | "generated_by": "Paul Ramsey", 42 | "meta-spec": { 43 | "version": "1.0.0", 44 | "url": "http://pgxn.org/meta/spec.txt" 45 | }, 46 | "tags": [ 47 | "http", 48 | "curl", 49 | "web" 50 | ] 51 | } 52 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | 2 | MODULE_big = http 3 | OBJS = http.o 4 | EXTENSION = http 5 | 6 | DATA = $(wildcard *.sql) 7 | 8 | REGRESS = http 9 | EXTRA_CLEAN = 10 | 11 | CURL_CONFIG = curl-config 12 | PG_CONFIG = pg_config 13 | 14 | CFLAGS += $(shell $(CURL_CONFIG) --cflags) 15 | LIBS += $(shell $(CURL_CONFIG) --libs) 16 | SHLIB_LINK := $(LIBS) 17 | 18 | ifdef DEBUG 19 | COPT += -O0 -Werror -g 20 | endif 21 | 22 | PGXS := $(shell $(PG_CONFIG) --pgxs) 23 | include $(PGXS) 24 | 25 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # PostgreSQL HTTP Client 2 | 3 | [![CI](https://github.com/pramsey/pgsql-http/workflows/CI/badge.svg)](https://github.com/pramsey/pgsql-http/actions) 4 | 5 | ## Motivation 6 | 7 | Wouldn't it be nice to be able to write a trigger that called a web service? Either to get back a result, or to poke that service into refreshing itself against the new state of the database? 8 | 9 | This extension is for that. 10 | 11 | ## Examples 12 | 13 | URL encode a string. 14 | 15 | ```sql 16 | SELECT urlencode('my special string''s & things?'); 17 | ``` 18 | ``` 19 | urlencode 20 | ------------------------------------- 21 | my+special+string%27s+%26+things%3F 22 | (1 row) 23 | ``` 24 | 25 | URL encode a JSON associative array. 26 | 27 | ```sql 28 | SELECT urlencode(jsonb_build_object('name','Colin & James','rate','50%')); 29 | ``` 30 | ``` 31 | urlencode 32 | ------------------------------------- 33 | name=Colin+%26+James&rate=50%25 34 | (1 row) 35 | ``` 36 | 37 | Run a GET request and see the content. 38 | 39 | ```sql 40 | SELECT content 41 | FROM http_get('http://httpbun.com/ip'); 42 | ``` 43 | ``` 44 | content 45 | ----------------------------- 46 | {"origin":"24.69.186.43"} 47 | (1 row) 48 | ``` 49 | 50 | Run a GET request with an Authorization header. 51 | 52 | ```sql 53 | SELECT content::json->'headers'->>'Authorization' 54 | FROM http(( 55 | 'GET', 56 | 'http://httpbun.com/headers', 57 | http_headers('Authorization','Bearer eyJ0eXAiOiJKV1QiLCJhbGciOiJIUzI1NiJ9'), 58 | NULL, 59 | NULL 60 | )::http_request); 61 | ``` 62 | ``` 63 | content 64 | ---------------------------------------------- 65 | Bearer eyJ0eXAiOiJKV1QiLCJhbGciOiJIUzI1NiJ9 66 | (1 row) 67 | ``` 68 | 69 | Read the `status` and `content_type` fields out of a `http_response` object. 70 | 71 | ```sql 72 | SELECT status, content_type 73 | FROM http_get('http://httpbun.com/'); 74 | ``` 75 | ``` 76 | status | content_type 77 | --------+-------------------------- 78 | 200 | text/html; charset=utf-8 79 | (1 row) 80 | ``` 81 | 82 | Show all the `http_header` in an `http_response` object. 83 | 84 | ```sql 85 | SELECT (unnest(headers)).* 86 | FROM http_get('http://httpbun.com/'); 87 | ``` 88 | ``` 89 | field | value 90 | ------------------+-------------------------------------------------- 91 | Server | nginx 92 | Date | Wed, 26 Jul 2023 19:52:51 GMT 93 | Content-Type | text/html 94 | Content-Length | 162 95 | Connection | close 96 | Location | https://httpbun.org 97 | server | nginx 98 | date | Wed, 26 Jul 2023 19:52:51 GMT 99 | content-type | text/html 100 | x-powered-by | httpbun/3c0dc05883dd9212ac38b04705037d50b02f2596 101 | content-encoding | gzip 102 | ``` 103 | 104 | Use the PUT command to send a simple text document to a server. 105 | 106 | ```sql 107 | SELECT status, content_type, content::json->>'data' AS data 108 | FROM http_put('http://httpbun.com/put', 'some text', 'text/plain'); 109 | ``` 110 | ``` 111 | status | content_type | data 112 | --------+------------------+----------- 113 | 200 | application/json | some text 114 | ``` 115 | 116 | Use the PATCH command to send a simple JSON document to a server. 117 | 118 | ```sql 119 | SELECT status, content_type, content::json->>'data' AS data 120 | FROM http_patch('http://httpbun.com/patch', '{"this":"that"}', 'application/json'); 121 | ``` 122 | ``` 123 | status | content_type | data 124 | --------+------------------+------------------ 125 | 200 | application/json | '{"this":"that"}' 126 | ``` 127 | 128 | Use the DELETE command to request resource deletion. 129 | 130 | ```sql 131 | SELECT status, content_type, content::json->>'url' AS url 132 | FROM http_delete('http://httpbun.com/delete'); 133 | ``` 134 | ``` 135 | status | content_type | url 136 | --------+------------------+--------------------------- 137 | 200 | application/json | http://httpbun.com/delete 138 | ``` 139 | 140 | As a shortcut to send data to a GET request, pass a JSONB data argument. 141 | 142 | ```sql 143 | SELECT status, content::json->'args' AS args 144 | FROM http_get('http://httpbun.com/get', 145 | jsonb_build_object('myvar','myval','foo','bar')); 146 | ``` 147 | 148 | To POST to a URL using a data payload instead of parameters embedded in the URL, encode the data in a JSONB as a data payload. 149 | 150 | ```sql 151 | SELECT status, content::json->'form' AS form 152 | FROM http_post('http://httpbun.com/post', 153 | jsonb_build_object('myvar','myval','foo','bar')); 154 | ``` 155 | 156 | To access binary content, you must coerce the content from the default `varchar` representation to a `bytea` representation using the `text_to_bytea()` function, or the `textsend()` function. Using the default `varchar::bytea` cast will **not work**, as the cast will stop the first time it hits a zero-valued byte (common in binary data). 157 | 158 | ```sql 159 | WITH 160 | http AS ( 161 | SELECT * FROM http_get('https://httpbingo.org/image/png') 162 | ), 163 | headers AS ( 164 | SELECT (unnest(headers)).* FROM http 165 | ) 166 | SELECT 167 | http.content_type, 168 | length(text_to_bytea(http.content)) AS length_binary 169 | FROM http, headers 170 | WHERE field ilike 'Content-Type'; 171 | ``` 172 | ``` 173 | content_type | length_binary 174 | --------------+--------------- 175 | image/png | 8090 176 | ``` 177 | Similarly, when using POST to send `bytea` binary content to a service, use the `bytea_to_text` function to prepare the content. 178 | 179 | To access only the headers you can do a HEAD-Request. This will not follow redirections. 180 | 181 | ```sql 182 | SELECT 183 | http.status, 184 | headers.value AS location 185 | FROM 186 | http_head('http://google.com') AS http 187 | LEFT OUTER JOIN LATERAL (SELECT value 188 | FROM unnest(http.headers) 189 | WHERE field = 'Location') AS headers 190 | ON true; 191 | ``` 192 | ``` 193 | status | location 194 | --------+------------------------ 195 | 301 | http://www.google.com/ 196 | ``` 197 | 198 | ## Concepts 199 | 200 | Every HTTP call is a made up of an `http_request` and an `http_response`. 201 | 202 | Composite type "public.http_request" 203 | Column | Type | Modifiers 204 | --------------+-------------------+----------- 205 | method | http_method | 206 | uri | character varying | 207 | headers | http_header[] | 208 | content_type | character varying | 209 | content | character varying | 210 | 211 | Composite type "public.http_response" 212 | Column | Type | Modifiers 213 | --------------+-------------------+----------- 214 | status | integer | 215 | content_type | character varying | 216 | headers | http_header[] | 217 | content | character varying | 218 | 219 | The utility functions, `http_get()`, `http_post()`, `http_put()`, `http_delete()` and `http_head()` are just wrappers around a master function, `http(http_request)` that returns `http_response`. 220 | 221 | The `headers` field for requests and response is a PostgreSQL array of type `http_header` which is just a simple tuple. 222 | 223 | Composite type "public.http_header" 224 | Column | Type | Modifiers 225 | --------+-------------------+----------- 226 | field | character varying | 227 | value | character varying | 228 | 229 | As seen in the examples, you can unspool the array of `http_header` tuples into a result set using the PostgreSQL `unnest()` function on the array. From there you select out the particular header you are interested in. 230 | 231 | ## Functions 232 | 233 | * `http_header(field VARCHAR, value VARCHAR)` returns `http_header` 234 | * `http_headers(field VARCHAR, value VARCHAR, ...)` returns `http_header[]` 235 | * `http(request http_request)` returns `http_response` 236 | * `http_get(uri VARCHAR)` returns `http_response` 237 | * `http_get(uri VARCHAR, data JSONB)` returns `http_response` 238 | * `http_post(uri VARCHAR, content VARCHAR, content_type VARCHAR)` returns `http_response` 239 | * `http_post(uri VARCHAR, data JSONB)` returns `http_response` 240 | * `http_put(uri VARCHAR, content VARCHAR, content_type VARCHAR)` returns `http_response` 241 | * `http_patch(uri VARCHAR, content VARCHAR, content_type VARCHAR)` returns `http_response` 242 | * `http_delete(uri VARCHAR, content VARCHAR, content_type VARCHAR))` returns `http_response` 243 | * `http_head(uri VARCHAR)` returns `http_response` 244 | * `http_set_curlopt(curlopt VARCHAR, value varchar)` returns `boolean` 245 | * `http_reset_curlopt()` returns `boolean` 246 | * `http_list_curlopt()` returns `setof(curlopt text, value text)` 247 | * `urlencode(string VARCHAR)` returns `text` 248 | * `urlencode(data JSONB)` returns `text` 249 | 250 | ## CURL Options 251 | 252 | Select [CURL options](https://curl.se/libcurl/c/curl_easy_setopt.html) are available to set using the SQL `SET` command and the appropriate option name. 253 | 254 | * [CURLOPT_CAINFO](https://curl.se/libcurl/c/CURLOPT_CAINFO.html) 255 | * [CURLOPT_CONNECTTIMEOUT](https://curl.se/libcurl/c/CURLOPT_CONNECTTIMEOUT.html) 256 | * [CURLOPT_CONNECTTIMEOUT_MS](https://curl.se/libcurl/c/CURLOPT_CONNECTTIMEOUT_MS.html) 257 | * [CURLOPT_DNS_SERVERS](https://curl.se/libcurl/c/CURLOPT_DNS_SERVERS.html) 258 | * [CURLOPT_PRE_PROXY](https://curl.se/libcurl/c/CURLOPT_PRE_PROXY.html) 259 | * [CURLOPT_PROXY](https://curl.se/libcurl/c/CURLOPT_PROXY.html) 260 | * [CURLOPT_PROXYPASSWORD](https://curl.se/libcurl/c/CURLOPT_PROXYPASSWORD.html) 261 | * [CURLOPT_PROXYPORT](https://curl.se/libcurl/c/CURLOPT_PROXYPORT.html) 262 | * [CURLOPT_PROXYUSERPWD](https://curl.se/libcurl/c/CURLOPT_PROXYUSERPWD.html) 263 | * [CURLOPT_PROXYUSERNAME](https://curl.se/libcurl/c/CURLOPT_PROXYUSERNAME.html) 264 | * [CURLOPT_PROXY_TLSAUTH_USERNAME](https://curl.se/libcurl/c/CURLOPT_PROXY_TLSAUTH_USERNAME.html) 265 | * [CURLOPT_PROXY_TLSAUTH_PASSWORD](https://curl.se/libcurl/c/CURLOPT_PROXY_TLSAUTH_PASSWORD.html) 266 | * [CURLOPT_PROXY_TLSAUTH_TYPE](https://curl.se/libcurl/c/CURLOPT_PROXY_TLSAUTH_TYPE.html) 267 | * [CURLOPT_SSL_VERIFYHOST](https://curl.se/libcurl/c/CURLOPT_SSL_VERIFYHOST.html) 268 | * [CURLOPT_SSL_VERIFYPEER](https://curl.se/libcurl/c/CURLOPT_SSL_VERIFYPEER.html) 269 | * [CURLOPT_SSLCERT](https://curl.se/libcurl/c/CURLOPT_SSLCERT.html) 270 | * [CURLOPT_SSLCERT_BLOB](https://curl.se/libcurl/c/CURLOPT_SSLCERT_BLOB.html) 271 | * [CURLOPT_SSLCERTTYPE](https://curl.se/libcurl/c/CURLOPT_SSLCERTTYPE.html) 272 | * [CURLOPT_SSLKEY](https://curl.se/libcurl/c/CURLOPT_SSLKEY.html) 273 | * [CURLOPT_SSLKEY_BLOB](https://curl.se/libcurl/c/CURLOPT_SSLKEY_BLOB.html) 274 | * [CURLOPT_TCP_KEEPALIVE](https://curl.se/libcurl/c/CURLOPT_TCP_KEEPALIVE.html) 275 | * [CURLOPT_TCP_KEEPIDLE](https://curl.se/libcurl/c/CURLOPT_TCP_KEEPIDLE.html) 276 | * [CURLOPT_TIMEOUT](https://curl.se/libcurl/c/CURLOPT_TIMEOUT.html) 277 | * [CURLOPT_TIMEOUT_MS](https://curl.se/libcurl/c/CURLOPT_TIMEOUT_MS.html) 278 | * [CURLOPT_TLSAUTH_USERNAME](https://curl.se/libcurl/c/CURLOPT_TLSAUTH_USERNAME.html) 279 | * [CURLOPT_TLSAUTH_PASSWORD](https://curl.se/libcurl/c/CURLOPT_TLSAUTH_PASSWORD.html) 280 | * [CURLOPT_TLSAUTH_TYPE](https://curl.se/libcurl/c/CURLOPT_TLSAUTH_TYPE.html) 281 | * [CURLOPT_USERAGENT](https://curl.se/libcurl/c/CURLOPT_USERAGENT.html) 282 | * [CURLOPT_USERPWD](https://curl.se/libcurl/c/CURLOPT_USERPWD.html) 283 | 284 | For example, 285 | 286 | ```sql 287 | -- Set the curlopt_proxyport option 288 | SET http.curlopt_proxyport = '12345'; 289 | 290 | -- View the curlopt_proxyport option 291 | SHOW http.curlopt_proxyport; 292 | 293 | -- View *all* currently set options 294 | SELECT * FROM http_list_curlopt(); 295 | ``` 296 | 297 | Will set the proxy port option for the lifetime of the database connection. You can reset all CURL options to their defaults using the `http_reset_curlopt()` function. 298 | 299 | You can permanently set the CURL options for a database or role, using the `ALTER DATABASE` and `ALTER ROLE` commands. 300 | 301 | ```sql 302 | -- Applies to all roles in the database 303 | ALTER DATABASE mydb SET http.curlopt_tlsauth_password = 'secret'; 304 | 305 | -- Applies to just one role in the database 306 | ALTER ROLE myapp IN mydb SET http.curlopt_tlsauth_password = 'secret'; 307 | ``` 308 | 309 | ## User Agents 310 | 311 | Using this extension as a background automated process without supervision (e.g as a trigger) may have unintended consequences for other servers. It is considered a best practice to share contact information with your requests, so that administrators can reach you in case your HTTP calls get out of control. 312 | 313 | Certain API policies (e.g. [Wikimedia User-Agent policy](https://foundation.wikimedia.org/wiki/Policy:Wikimedia_Foundation_User-Agent_Policy)) may even require sharing specific contact information with each request. Others may disallow (via `robots.txt`) certain agents they don't recognize. 314 | 315 | For such cases you can set the `CURLOPT_USERAGENT` option 316 | 317 | ```sql 318 | SET http.curlopt_useragent = 'PgBot/2.1 (+http://pgbot.com/bot.html) Contact abuse@pgbot.com'; 319 | 320 | SELECT status, content::json->'headers'->>'User-Agent' 321 | FROM http_get('http://httpbun.com/headers'); 322 | ``` 323 | ``` 324 | status | user_agent 325 | --------+----------------------------------------------------------- 326 | 200 | PgBot/2.1 (+http://pgbot.com/bot.html) Contact abuse@pgbot.com 327 | ``` 328 | 329 | ## Keep-Alive & Timeouts 330 | 331 | By default each request uses a fresh connection and assures that the connection is closed when the request is done. This behavior reduces the chance of consuming system resources (sockets) as the extension runs over extended periods of time. 332 | 333 | High-performance applications may wish to enable keep-alive and connection persistence to reduce latency and enhance throughput. The following GUC variable changes the behavior of the http extension to maintain connections as long as possible: 334 | 335 | ```sql 336 | SET http.curlopt_tcp_keepalive = 1; 337 | ``` 338 | 339 | By default a 5 second timeout is set for the completion of a request. If a different timeout is desired the following GUC variable can be used to set it in milliseconds: 340 | 341 | ```sql 342 | SET http.curlopt_timeout_msec = 200; 343 | ``` 344 | 345 | ## Installation 346 | 347 | ### Debian / Ubuntu apt.postgresql.org 348 | Replace 17 with your version of PostgreSQL 349 | ``` 350 | apt install postgresql-17-http 351 | ``` 352 | 353 | ### Compile from Source 354 | 355 | #### General Unix 356 | 357 | If you have PostgreSQL devel packages and CURL devel packages installed, you should have `pg_config` and `curl-config` on your path, so you should be able to just run `make` (or `gmake`), then `make install`, then in your database `CREATE EXTENSION http`. 358 | 359 | If you already installed a previous version and you just want to upgrade, then `ALTER EXTENSION http UPDATE`. 360 | 361 | #### Debian / Ubuntu / APT 362 | 363 | Refer to https://wiki.postgresql.org/wiki/Apt for pulling packages from apt.postgresql.org repository. 364 | 365 | ```bash 366 | sudo apt install \ 367 | postgresql-server-dev-14 \ 368 | libcurl4-openssl-dev \ 369 | make \ 370 | g++ 371 | 372 | make 373 | sudo make install 374 | ``` 375 | 376 | If there several PostgreSQL installations available, you might need to edit the Makefile before running `make`: 377 | 378 | ``` 379 | #PG_CONFIG = pg_config 380 | PG_CONFIG = /usr/lib/postgresql/14/bin/pg_config 381 | ``` 382 | 383 | ### Windows 384 | 385 | There is a build available at [postgresonline](http://www.postgresonline.com/journal/archives/371-http-extension.html), not maintained by me. 386 | 387 | ### Testing 388 | 389 | The integration tests are run with `make install && make installcheck` and expect to find a running instance of [httpbin](http://httpbin.org) at port 9080. The easiest way to get that is: 390 | 391 | ``` 392 | docker run -p 9080:80 kennethreitz/httpbin 393 | ``` 394 | 395 | ## Why This is a Bad Idea 396 | 397 | - "What happens if the web page takes a long time to return?" Your SQL call will just wait there until it does. Make sure your web service fails fast. Or (dangerous in a different way) run your query within [pg_background](https://github.com/vibhorkum/pg_background) or on a schedule with [pg_cron](https://github.com/citusdata/pg_cron). 398 | - "What if the web page returns junk?" Your SQL call will have to test for junk before doing anything with the payload. 399 | - "What if the web page never returns?" Set a short timeout, or send a cancel to the request, or just wait forever. 400 | - "What if a user queries a page they shouldn't?" Restrict function access, or just don't install a footgun like this extension where users can access it. 401 | 402 | ## To Do 403 | 404 | - The [background worker](https://www.postgresql.org/docs/current/bgworker.html) support could be used to set up an HTTP request queue, so that pgsql-http can register a request and callback and then return immediately. 405 | 406 | -------------------------------------------------------------------------------- /ci/pg_hba.conf: -------------------------------------------------------------------------------- 1 | # TYPE DATABASE USER ADDRESS METHOD 2 | 3 | # "local" is for Unix domain socket connections only 4 | local all postgres trust 5 | # IPv4 local connections: 6 | host all postgres 127.0.0.1/32 trust 7 | # IPv6 local connections: 8 | host all postgres ::1/128 trust 9 | -------------------------------------------------------------------------------- /examples/s3.sql: -------------------------------------------------------------------------------- 1 | 2 | -- 3 | -- s3_get 4 | -- 5 | -- Installation: 6 | -- 7 | -- CREATE EXTENSION pgcrypto; 8 | -- CREATE EXTENSION http; 9 | -- 10 | -- Utility function to take S3 object and access keys and create 11 | -- a signed HTTP GET request using the AWS4 signing scheme. 12 | -- https://docs.aws.amazon.com/AmazonS3/latest/API/sig-v4-authenticating-requests.html 13 | -- 14 | -- Various pieces of the request are gathered into strings bundled together 15 | -- and ultimately signed with the s3 secret key. 16 | -- 17 | -- Example: 18 | -- 19 | -- https://cleverelephant-west-1.s3.amazonaws.com/META.json 20 | -- 21 | -- SELECT * FROM s3_get( 22 | -- 'your_s3_access_key', -- access 23 | -- 'your_s3_secret_key', -- secret 24 | -- 'us-west-1', -- region 25 | -- 'cleverelephant-west-1', -- bucket 26 | -- 'META.json' -- object 27 | -- ); 28 | -- 29 | CREATE OR REPLACE FUNCTION s3_get( 30 | access_key TEXT, 31 | secret_key TEXT, 32 | region TEXT, 33 | bucket TEXT, 34 | object_key TEXT 35 | ) RETURNS http_response AS $$ 36 | DECLARE 37 | http_method TEXT := 'GET'; 38 | host TEXT := bucket || '.s3.' || region || '.amazonaws.com'; 39 | endpoint TEXT := 'https://' || host || '/' || object_key; 40 | canonical_uri TEXT := '/' || object_key; 41 | canonical_querystring TEXT := ''; 42 | signed_headers TEXT := 'host;x-amz-content-sha256;x-amz-date'; 43 | service TEXT := 's3'; 44 | 45 | now TIMESTAMP := now() AT TIME ZONE 'UTC'; 46 | amz_date TEXT := to_char(now, 'YYYYMMDD"T"HH24MISS"Z"'); 47 | date_stamp TEXT := to_char(now, 'YYYYMMDD'); 48 | empty_payload_hash TEXT := 'e3b0c44298fc1c149afbf4c8996fb92427ae41e4649b934ca495991b7852b855'; 49 | 50 | canonical_headers TEXT; 51 | canonical_request TEXT; 52 | string_to_sign TEXT; 53 | credential_scope TEXT; 54 | date_key BYTEA; 55 | date_region_key BYTEA; 56 | date_region_service_key BYTEA; 57 | signing_key BYTEA; 58 | signature TEXT; 59 | authorization_header TEXT; 60 | canonical_request_digest TEXT; 61 | response http_response; 62 | request http_request; 63 | BEGIN 64 | 65 | -- Construct the canonical headers 66 | canonical_headers := 'host:' || host || E'\n' 67 | || 'x-amz-content-sha256:' || empty_payload_hash || E'\n' 68 | || 'x-amz-date:' || amz_date || E'\n'; 69 | 70 | -- Create the canonical request 71 | canonical_request := http_method || E'\n' || 72 | canonical_uri || E'\n' || 73 | canonical_querystring || E'\n' || 74 | canonical_headers || E'\n' || 75 | signed_headers || E'\n' || 76 | empty_payload_hash; 77 | 78 | -- Define the credential scope 79 | credential_scope := date_stamp || '/' || region || '/' || service || '/aws4_request'; 80 | 81 | -- Get sha256 hash of request 82 | canonical_request_digest := encode(digest(canonical_request, 'sha256'), 'hex'); 83 | 84 | -- Create the string to sign 85 | string_to_sign := 'AWS4-HMAC-SHA256' || E'\n' || 86 | amz_date || E'\n' || 87 | credential_scope || E'\n' || 88 | canonical_request_digest; 89 | 90 | -- 91 | -- Signature of pgcrypto function is hmac(payload, secret, algo) 92 | -- Each piece of the signing key is bundled together with the 93 | -- previous piece, starting with the S3 secret key. 94 | -- 95 | date_key := hmac(convert_to(date_stamp, 'UTF8'), convert_to('AWS4' || secret_key, 'UTF8'), 'sha256'); 96 | date_region_key := hmac(convert_to(region, 'UTF8'), date_key, 'sha256'); 97 | date_region_service_key := hmac(convert_to(service, 'UTF8'), date_region_key, 'sha256'); 98 | signing_key := hmac(convert_to('aws4_request','UTF8'), date_region_service_key, 'sha256'); 99 | 100 | -- Compute the signature 101 | signature := encode(hmac(convert_to(string_to_sign, 'UTF8'), signing_key, 'sha256'), 'hex'); 102 | 103 | -- Construct the Authorization header 104 | authorization_header := 'AWS4-HMAC-SHA256 Credential=' || access_key || '/' || credential_scope || 105 | ', SignedHeaders=' || signed_headers || 106 | ', Signature=' || signature; 107 | 108 | 109 | -- Perform the HTTP request 110 | request := ( 111 | 'GET', 112 | endpoint, 113 | http_headers('Authorization', authorization_header, 114 | 'x-amz-content-sha256', empty_payload_hash, 115 | 'x-amz-date', amz_date, 116 | 'host', host), 117 | NULL, 118 | NULL 119 | )::http_request; 120 | 121 | -- Getting the canonical request and payload strings perfectly 122 | -- formatted is an important step so debugging here in case 123 | -- S3 rejects signed request 124 | RAISE DEBUG 's3_get, canonical_request: %', canonical_request; 125 | RAISE DEBUG 's3_get, string_to_sign: %', string_to_sign; 126 | RAISE DEBUG 's3_get, request %', request; 127 | 128 | RETURN http(request); 129 | 130 | END; 131 | $$ LANGUAGE 'plpgsql' 132 | VOLATILE; 133 | 134 | 135 | 136 | 137 | -------------------------------------------------------------------------------- /expected/http.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION http; 2 | SET http.server_host = 'http://localhost:9080'; 3 | set http.timeout_msec = 10000; 4 | SELECT http_set_curlopt('CURLOPT_TIMEOUT', '10'); 5 | http_set_curlopt 6 | ------------------ 7 | t 8 | (1 row) 9 | 10 | -- if local server not up use global one 11 | DO language plpgsql $$ 12 | BEGIN 13 | BEGIN 14 | PERFORM http_get(current_setting('http.server_host') || '/status/202'); 15 | EXCEPTION WHEN OTHERS THEN 16 | SET http.server_host = 'http://httpbin.org'; 17 | END; 18 | END; 19 | $$; 20 | -- Status code 21 | SELECT status 22 | FROM http_get(current_setting('http.server_host') || '/status/202'); 23 | status 24 | -------- 25 | 202 26 | (1 row) 27 | 28 | -- Headers 29 | SELECT lower(field) AS field, value 30 | FROM ( 31 | SELECT (unnest(headers)).* 32 | FROM http_get(current_setting('http.server_host') || '/response-headers?Abcde=abcde') 33 | ) a 34 | WHERE field ILIKE 'Abcde'; 35 | field | value 36 | -------+------- 37 | abcde | abcde 38 | (1 row) 39 | 40 | -- GET 41 | SELECT status, 42 | content::json->'args'->>'foo' AS args, 43 | content::json->>'method' AS method 44 | FROM http_get(current_setting('http.server_host') || '/anything?foo=bar'); 45 | status | args | method 46 | --------+------+-------- 47 | 200 | bar | GET 48 | (1 row) 49 | 50 | -- GET with data 51 | SELECT status, 52 | content::json->'args'->>'this' AS args, 53 | replace(content::json->>'url',current_setting('http.server_host'),'') AS path, 54 | content::json->>'method' AS method 55 | FROM http_get(current_setting('http.server_host') || '/anything', jsonb_build_object('this', 'that')); 56 | status | args | path | method 57 | --------+------+---------------------+-------- 58 | 200 | that | /anything?this=that | GET 59 | (1 row) 60 | 61 | -- GET with data 62 | SELECT status, 63 | content::json->>'args' as args, 64 | (content::json)->>'data' as data, 65 | content::json->>'method' as method 66 | FROM http(('GET', current_setting('http.server_host') || '/anything', NULL, 'application/json', '{"search": "toto"}')); 67 | status | args | data | method 68 | --------+------+--------------------+-------- 69 | 200 | {} | {"search": "toto"} | GET 70 | (1 row) 71 | 72 | -- DELETE 73 | SELECT status, 74 | content::json->'args'->>'foo' AS args, 75 | replace(content::json->>'url',current_setting('http.server_host'),'') AS path, 76 | content::json->>'method' AS method 77 | FROM http_delete(current_setting('http.server_host') || '/anything?foo=bar'); 78 | status | args | path | method 79 | --------+------+-------------------+-------- 80 | 200 | bar | /anything?foo=bar | DELETE 81 | (1 row) 82 | 83 | -- DELETE with payload 84 | SELECT status, 85 | content::json->'args'->>'foo' AS args, 86 | replace(content::json->>'url',current_setting('http.server_host'),'') AS path, 87 | content::json->>'method' AS method, 88 | content::json->>'data' AS data 89 | FROM http_delete(current_setting('http.server_host') || '/anything?foo=bar', 'payload', 'text/plain'); 90 | status | args | path | method | data 91 | --------+------+-------------------+--------+--------- 92 | 200 | bar | /anything?foo=bar | DELETE | payload 93 | (1 row) 94 | 95 | -- PUT 96 | SELECT status, 97 | content::json->>'data' AS data, 98 | content::json->'args'->>'foo' AS args, 99 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 100 | content::json->>'method' AS method 101 | FROM http_put(current_setting('http.server_host') || '/anything?foo=bar','payload','text/plain'); 102 | status | data | args | path | method 103 | --------+---------+------+-------------------+-------- 104 | 200 | payload | bar | /anything?foo=bar | PUT 105 | (1 row) 106 | 107 | -- PATCH 108 | SELECT status, 109 | content::json->>'data' AS data, 110 | content::json->'args'->>'foo' AS args, 111 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 112 | content::json->>'method' AS method 113 | FROM http_patch(current_setting('http.server_host') || '/anything?foo=bar','{"this":"that"}','application/json'); 114 | status | data | args | path | method 115 | --------+-----------------+------+-------------------+-------- 116 | 200 | {"this":"that"} | bar | /anything?foo=bar | PATCH 117 | (1 row) 118 | 119 | -- POST 120 | SELECT status, 121 | content::json->>'data' AS data, 122 | content::json->'args'->>'foo' AS args, 123 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 124 | content::json->>'method' AS method 125 | FROM http_post(current_setting('http.server_host') || '/anything?foo=bar','payload','text/plain'); 126 | status | data | args | path | method 127 | --------+---------+------+-------------------+-------- 128 | 200 | payload | bar | /anything?foo=bar | POST 129 | (1 row) 130 | 131 | -- POST with json data 132 | SELECT status, 133 | content::json->'form'->>'this' AS args, 134 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 135 | content::json->>'method' AS method 136 | FROM http_post(current_setting('http.server_host') || '/anything', jsonb_build_object('this', 'that')); 137 | status | args | path | method 138 | --------+------+-----------+-------- 139 | 200 | that | /anything | POST 140 | (1 row) 141 | 142 | -- POST with data 143 | SELECT status, 144 | content::json->'form'->>'key1' AS key1, 145 | content::json->'form'->>'key2' AS key2, 146 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 147 | content::json->>'method' AS method 148 | FROM http_post(current_setting('http.server_host') || '/anything', 'key1=value1&key2=value2','application/x-www-form-urlencoded'); 149 | status | key1 | key2 | path | method 150 | --------+--------+--------+-----------+-------- 151 | 200 | value1 | value2 | /anything | POST 152 | (1 row) 153 | 154 | -- HEAD 155 | SELECT lower(field) AS field, value 156 | FROM ( 157 | SELECT (unnest(headers)).* 158 | FROM http_head(current_setting('http.server_host') || '/response-headers?Abcde=abcde') 159 | ) a 160 | WHERE field ILIKE 'Abcde'; 161 | field | value 162 | -------+------- 163 | abcde | abcde 164 | (1 row) 165 | 166 | -- Follow redirect 167 | SELECT status, 168 | replace((content::json)->>'url', current_setting('http.server_host'),'') AS path 169 | FROM http_get(current_setting('http.server_host') || '/redirect-to?url=get'); 170 | status | path 171 | --------+------ 172 | 200 | /get 173 | (1 row) 174 | 175 | -- Request image 176 | WITH 177 | http AS ( 178 | SELECT * FROM http_get(current_setting('http.server_host') || '/image/png') 179 | ), 180 | headers AS ( 181 | SELECT (unnest(headers)).* FROM http 182 | ) 183 | SELECT 184 | http.content_type, 185 | length(text_to_bytea(http.content)) AS length_binary 186 | FROM http, headers 187 | WHERE field ilike 'Content-Type'; 188 | content_type | length_binary 189 | --------------+--------------- 190 | image/png | 8090 191 | (1 row) 192 | 193 | -- Alter options and and reset them and throw errors 194 | SELECT http_set_curlopt('CURLOPT_PROXY', '127.0.0.1'); 195 | http_set_curlopt 196 | ------------------ 197 | t 198 | (1 row) 199 | 200 | -- Error because proxy is not there 201 | DO $$ 202 | BEGIN 203 | SELECT status FROM http_get(current_setting('http.server_host') || '/status/555'); 204 | EXCEPTION 205 | WHEN OTHERS THEN 206 | RAISE WARNING 'Failed to connect'; 207 | END; 208 | $$; 209 | WARNING: Failed to connect 210 | -- Still an error 211 | DO $$ 212 | BEGIN 213 | SELECT status FROM http_get(current_setting('http.server_host') || '/status/555'); 214 | EXCEPTION 215 | WHEN OTHERS THEN 216 | RAISE WARNING 'Failed to connect'; 217 | END; 218 | $$; 219 | WARNING: Failed to connect 220 | -- Reset options 221 | SELECT http_reset_curlopt(); 222 | http_reset_curlopt 223 | -------------------- 224 | t 225 | (1 row) 226 | 227 | -- Now it should work 228 | SELECT status FROM http_get(current_setting('http.server_host') || '/status/555'); 229 | status 230 | -------- 231 | 555 232 | (1 row) 233 | 234 | -- Alter the default timeout and then run a query that is longer than 235 | -- the default (5s), but shorter than the new timeout 236 | SELECT http_set_curlopt('CURLOPT_TIMEOUT_MS', '10000'); 237 | http_set_curlopt 238 | ------------------ 239 | t 240 | (1 row) 241 | 242 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 243 | status 244 | -------- 245 | 200 246 | (1 row) 247 | 248 | -- Test new GUC feature 249 | SET http.CURLOPT_TIMEOUT_MS = '10'; 250 | -- should fail 251 | -- Still an error 252 | DO $$ 253 | BEGIN 254 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 255 | EXCEPTION 256 | WHEN OTHERS THEN 257 | RAISE WARNING 'Failed to connect'; 258 | END; 259 | $$; 260 | WARNING: Failed to connect 261 | SET http.CURLOPT_TIMEOUT_MS = '10000'; 262 | --should pass 263 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 264 | status 265 | -------- 266 | 200 267 | (1 row) 268 | 269 | -- SET to bogus file 270 | SET http.CURLOPT_CAINFO = '/path/to/somebundle.crt'; 271 | -- should fail 272 | DO $$ 273 | BEGIN 274 | SELECT status FROM http_get('https://postgis.net'); 275 | EXCEPTION 276 | WHEN OTHERS THEN 277 | RAISE WARNING 'Invalid cert file'; 278 | END; 279 | $$; 280 | WARNING: Invalid cert file 281 | -- set to ignore cert 282 | SET http.CURLOPT_SSL_VERIFYPEER = '0'; 283 | -- should pass 284 | SELECT status FROM http_get('https://postgis.net'); 285 | status 286 | -------- 287 | 200 288 | (1 row) 289 | 290 | SHOW http.CURLOPT_CAINFO; 291 | http.curlopt_cainfo 292 | ------------------------- 293 | /path/to/somebundle.crt 294 | (1 row) 295 | 296 | -- reset it 297 | RESET http.CURLOPT_CAINFO; 298 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 299 | status 300 | -------- 301 | 200 302 | (1 row) 303 | 304 | -- Check that statement interruption works 305 | SET statement_timeout = 200; 306 | CREATE TEMPORARY TABLE timer AS 307 | SELECT now() AS start; 308 | SELECT * 309 | FROM http_get(current_setting('http.server_host') || '/delay/7'); 310 | ERROR: canceling statement due to user request 311 | SELECT round(extract(epoch FROM now() - start) * 10) AS m 312 | FROM timer; 313 | m 314 | --- 315 | 2 316 | (1 row) 317 | 318 | DROP TABLE timer; 319 | -------------------------------------------------------------------------------- /http--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | 2 | -- Remove old 1.0 functions 3 | DROP FUNCTION http_get(varchar, varchar); 4 | DROP FUNCTION http_post(varchar, varchar, varchar, varchar); 5 | 6 | CREATE DOMAIN http_method AS text 7 | CHECK ( 8 | VALUE ILIKE 'get' OR 9 | VALUE ILIKE 'post' OR 10 | VALUE ILIKE 'put' OR 11 | VALUE ILIKE 'delete' 12 | ); 13 | 14 | CREATE DOMAIN content_type AS text 15 | CHECK ( 16 | VALUE ~ '^\S+\/\S+' 17 | ); 18 | 19 | CREATE TYPE http_header AS ( 20 | field VARCHAR, 21 | value VARCHAR 22 | ); 23 | 24 | CREATE TYPE http_request AS ( 25 | method http_method, 26 | uri VARCHAR, 27 | headers http_header[], 28 | content_type VARCHAR, 29 | content VARCHAR 30 | ); 31 | 32 | ALTER TYPE http_response ALTER ATTRIBUTE headers TYPE http_header[]; 33 | 34 | CREATE OR REPLACE FUNCTION http_header (field VARCHAR, value VARCHAR) 35 | RETURNS http_header 36 | AS $$ SELECT $1, $2 $$ 37 | LANGUAGE 'sql'; 38 | 39 | CREATE OR REPLACE FUNCTION http(request @extschema@.http_request) 40 | RETURNS http_response 41 | AS 'MODULE_PATHNAME', 'http_request' 42 | LANGUAGE 'c'; 43 | 44 | CREATE OR REPLACE FUNCTION http_get(uri VARCHAR) 45 | RETURNS http_response 46 | AS $$ SELECT @extschema@.http(('GET', $1, NULL, NULL, NULL)::http_request) $$ 47 | LANGUAGE 'sql'; 48 | 49 | CREATE OR REPLACE FUNCTION http_post(uri VARCHAR, content VARCHAR, content_type VARCHAR) 50 | RETURNS http_response 51 | AS $$ SELECT @extschema@.http(('POST', $1, NULL, $3, $2)::http_request) $$ 52 | LANGUAGE 'sql'; 53 | 54 | CREATE OR REPLACE FUNCTION http_put(uri VARCHAR, content VARCHAR, content_type VARCHAR) 55 | RETURNS http_response 56 | AS $$ SELECT @extschema@.http(('PUT', $1, NULL, $3, $2)::http_request) $$ 57 | LANGUAGE 'sql'; 58 | 59 | CREATE OR REPLACE FUNCTION http_delete(uri VARCHAR) 60 | RETURNS http_response 61 | AS $$ SELECT @extschema@.http(('DELETE', $1, NULL, NULL, NULL)::http_request) $$ 62 | LANGUAGE 'sql'; 63 | 64 | CREATE OR REPLACE FUNCTION urlencode(string VARCHAR) 65 | RETURNS TEXT 66 | AS 'MODULE_PATHNAME' 67 | LANGUAGE 'c' 68 | IMMUTABLE STRICT; 69 | -------------------------------------------------------------------------------- /http--1.1--1.2.sql: -------------------------------------------------------------------------------- 1 | 2 | ALTER DOMAIN http_method DROP CONSTRAINT http_method_check; 3 | ALTER DOMAIN http_method ADD CHECK ( 4 | VALUE ILIKE 'get' OR 5 | VALUE ILIKE 'post' OR 6 | VALUE ILIKE 'put' OR 7 | VALUE ILIKE 'delete' OR 8 | VALUE ILIKE 'head' 9 | ); 10 | 11 | CREATE OR REPLACE FUNCTION http_head(uri VARCHAR) 12 | RETURNS http_response 13 | AS $$ SELECT @extschema@.http(('HEAD', $1, NULL, NULL, NULL)::http_request) $$ 14 | LANGUAGE 'sql'; 15 | 16 | CREATE OR REPLACE FUNCTION http_set_curlopt (curlopt VARCHAR, value VARCHAR) 17 | RETURNS boolean 18 | AS 'MODULE_PATHNAME', 'http_set_curlopt' 19 | LANGUAGE 'c'; 20 | 21 | CREATE OR REPLACE FUNCTION http_reset_curlopt () 22 | RETURNS boolean 23 | AS 'MODULE_PATHNAME', 'http_reset_curlopt' 24 | LANGUAGE 'c'; 25 | -------------------------------------------------------------------------------- /http--1.2--1.3.sql: -------------------------------------------------------------------------------- 1 | ALTER DOMAIN http_method DROP CONSTRAINT http_method_check; 2 | ALTER DOMAIN http_method ADD CHECK ( 3 | VALUE ILIKE 'get' OR 4 | VALUE ILIKE 'post' OR 5 | VALUE ILIKE 'put' OR 6 | VALUE ILIKE 'delete' OR 7 | VALUE ILIKE 'patch' OR 8 | VALUE ILIKE 'head' 9 | ); 10 | 11 | CREATE OR REPLACE FUNCTION http_patch(uri VARCHAR, content VARCHAR, content_type VARCHAR) 12 | RETURNS http_response 13 | AS $$ SELECT @extschema@.http(('PATCH', $1, NULL, $3, $2)::http_request) $$ 14 | LANGUAGE 'sql'; 15 | -------------------------------------------------------------------------------- /http--1.3--1.4.sql: -------------------------------------------------------------------------------- 1 | CREATE OR REPLACE FUNCTION http_list_curlopt () 2 | RETURNS TABLE(curlopt text, value text) 3 | AS 'MODULE_PATHNAME', 'http_list_curlopt' 4 | LANGUAGE 'c'; 5 | 6 | CREATE OR REPLACE FUNCTION urlencode(string BYTEA) 7 | RETURNS TEXT 8 | AS 'MODULE_PATHNAME' 9 | LANGUAGE 'c' 10 | IMMUTABLE STRICT; 11 | 12 | CREATE OR REPLACE FUNCTION urlencode(data JSONB) 13 | RETURNS TEXT 14 | AS 'MODULE_PATHNAME' 15 | LANGUAGE 'c' 16 | IMMUTABLE STRICT; 17 | 18 | CREATE OR REPLACE FUNCTION http_get(uri VARCHAR, data JSONB) 19 | RETURNS http_response 20 | AS $$ SELECT @extschema@.http(('GET', $1 || '?' || @extschema@.urlencode($2), NULL, NULL, NULL)::http_request) $$ 21 | LANGUAGE 'sql'; 22 | 23 | CREATE OR REPLACE FUNCTION http_post(uri VARCHAR, data JSONB) 24 | RETURNS http_response 25 | AS $$ SELECT @extschema@.http(('POST', $1, NULL, 'application/x-www-form-urlencoded', @extschema@.urlencode($2))::http_request) $$ 26 | LANGUAGE 'sql'; 27 | -------------------------------------------------------------------------------- /http--1.4--1.5.sql: -------------------------------------------------------------------------------- 1 | 2 | CREATE OR REPLACE FUNCTION http_delete(uri VARCHAR, content VARCHAR, content_type VARCHAR) 3 | RETURNS http_response 4 | AS $$ SELECT @extschema@.http(('DELETE', $1, NULL, $3, $2)::@extschema@.http_request) $$ 5 | LANGUAGE 'sql'; 6 | -------------------------------------------------------------------------------- /http--1.5--1.6.sql: -------------------------------------------------------------------------------- 1 | 2 | ALTER DOMAIN http_method DROP CONSTRAINT IF EXISTS http_method_check; 3 | 4 | CREATE FUNCTION text_to_bytea(data TEXT) 5 | RETURNS BYTEA 6 | AS 'MODULE_PATHNAME', 'text_to_bytea' 7 | LANGUAGE 'c' 8 | IMMUTABLE STRICT; 9 | 10 | CREATE FUNCTION bytea_to_text(data BYTEA) 11 | RETURNS TEXT 12 | AS 'MODULE_PATHNAME', 'bytea_to_text' 13 | LANGUAGE 'c' 14 | IMMUTABLE STRICT; 15 | -------------------------------------------------------------------------------- /http--1.6--1.7.sql: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/pramsey/pgsql-http/5b57e0ec52077ffa92637121162bcd536e48f399/http--1.6--1.7.sql -------------------------------------------------------------------------------- /http--1.7.sql: -------------------------------------------------------------------------------- 1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 2 | \echo Use "CREATE EXTENSION http" to load this file. \quit 3 | CREATE DOMAIN http_method AS text; 4 | CREATE DOMAIN content_type AS text 5 | CHECK ( 6 | VALUE ~ '^\S+\/\S+' 7 | ); 8 | 9 | CREATE TYPE http_header AS ( 10 | field VARCHAR, 11 | value VARCHAR 12 | ); 13 | 14 | CREATE TYPE http_response AS ( 15 | status INTEGER, 16 | content_type VARCHAR, 17 | headers http_header[], 18 | content VARCHAR 19 | ); 20 | 21 | CREATE TYPE http_request AS ( 22 | method http_method, 23 | uri VARCHAR, 24 | headers http_header[], 25 | content_type VARCHAR, 26 | content VARCHAR 27 | ); 28 | 29 | CREATE FUNCTION http_set_curlopt (curlopt VARCHAR, value VARCHAR) 30 | RETURNS boolean 31 | AS 'MODULE_PATHNAME', 'http_set_curlopt' 32 | LANGUAGE 'c'; 33 | 34 | CREATE FUNCTION http_reset_curlopt () 35 | RETURNS boolean 36 | AS 'MODULE_PATHNAME', 'http_reset_curlopt' 37 | LANGUAGE 'c'; 38 | 39 | CREATE FUNCTION http_list_curlopt () 40 | RETURNS TABLE(curlopt text, value text) 41 | AS 'MODULE_PATHNAME', 'http_list_curlopt' 42 | LANGUAGE 'c'; 43 | 44 | CREATE FUNCTION http_header (field VARCHAR, value VARCHAR) 45 | RETURNS http_header 46 | AS $$ SELECT $1, $2 $$ 47 | LANGUAGE 'sql'; 48 | 49 | CREATE FUNCTION http(request @extschema@.http_request) 50 | RETURNS http_response 51 | AS 'MODULE_PATHNAME', 'http_request' 52 | LANGUAGE 'c'; 53 | 54 | CREATE FUNCTION http_get(uri VARCHAR) 55 | RETURNS http_response 56 | AS $$ SELECT @extschema@.http(('GET', $1, NULL, NULL, NULL)::@extschema@.http_request) $$ 57 | LANGUAGE 'sql'; 58 | 59 | CREATE FUNCTION http_post(uri VARCHAR, content VARCHAR, content_type VARCHAR) 60 | RETURNS http_response 61 | AS $$ SELECT @extschema@.http(('POST', $1, NULL, $3, $2)::@extschema@.http_request) $$ 62 | LANGUAGE 'sql'; 63 | 64 | CREATE FUNCTION http_put(uri VARCHAR, content VARCHAR, content_type VARCHAR) 65 | RETURNS http_response 66 | AS $$ SELECT @extschema@.http(('PUT', $1, NULL, $3, $2)::@extschema@.http_request) $$ 67 | LANGUAGE 'sql'; 68 | 69 | CREATE FUNCTION http_patch(uri VARCHAR, content VARCHAR, content_type VARCHAR) 70 | RETURNS http_response 71 | AS $$ SELECT @extschema@.http(('PATCH', $1, NULL, $3, $2)::@extschema@.http_request) $$ 72 | LANGUAGE 'sql'; 73 | 74 | CREATE FUNCTION http_delete(uri VARCHAR) 75 | RETURNS http_response 76 | AS $$ SELECT @extschema@.http(('DELETE', $1, NULL, NULL, NULL)::@extschema@.http_request) $$ 77 | LANGUAGE 'sql'; 78 | 79 | CREATE FUNCTION http_delete(uri VARCHAR, content VARCHAR, content_type VARCHAR) 80 | RETURNS http_response 81 | AS $$ SELECT @extschema@.http(('DELETE', $1, NULL, $3, $2)::@extschema@.http_request) $$ 82 | LANGUAGE 'sql'; 83 | 84 | CREATE FUNCTION http_head(uri VARCHAR) 85 | RETURNS http_response 86 | AS $$ SELECT @extschema@.http(('HEAD', $1, NULL, NULL, NULL)::@extschema@.http_request) $$ 87 | LANGUAGE 'sql'; 88 | 89 | CREATE FUNCTION urlencode(string VARCHAR) 90 | RETURNS TEXT 91 | AS 'MODULE_PATHNAME' 92 | LANGUAGE 'c' 93 | IMMUTABLE STRICT; 94 | 95 | CREATE FUNCTION urlencode(string BYTEA) 96 | RETURNS TEXT 97 | AS 'MODULE_PATHNAME' 98 | LANGUAGE 'c' 99 | IMMUTABLE STRICT; 100 | 101 | CREATE FUNCTION urlencode(data JSONB) 102 | RETURNS TEXT 103 | AS 'MODULE_PATHNAME', 'urlencode_jsonb' 104 | LANGUAGE 'c' 105 | IMMUTABLE STRICT; 106 | 107 | CREATE FUNCTION http_get(uri VARCHAR, data JSONB) 108 | RETURNS http_response 109 | AS $$ 110 | SELECT @extschema@.http(('GET', $1 || '?' || @extschema@.urlencode($2), NULL, NULL, NULL)::@extschema@.http_request) 111 | $$ 112 | LANGUAGE 'sql'; 113 | 114 | CREATE FUNCTION http_post(uri VARCHAR, data JSONB) 115 | RETURNS http_response 116 | AS $$ 117 | SELECT @extschema@.http(('POST', $1, NULL, 'application/x-www-form-urlencoded', @extschema@.urlencode($2))::@extschema@.http_request) 118 | $$ 119 | LANGUAGE 'sql'; 120 | 121 | CREATE FUNCTION text_to_bytea(data TEXT) 122 | RETURNS BYTEA 123 | AS 'MODULE_PATHNAME', 'text_to_bytea' 124 | LANGUAGE 'c' 125 | IMMUTABLE STRICT; 126 | 127 | CREATE FUNCTION bytea_to_text(data BYTEA) 128 | RETURNS TEXT 129 | AS 'MODULE_PATHNAME', 'bytea_to_text' 130 | LANGUAGE 'c' 131 | IMMUTABLE STRICT; 132 | 133 | CREATE FUNCTION http_headers(VARIADIC args text[]) 134 | RETURNS http_header[] AS $$ 135 | DECLARE 136 | headers http_header[]; 137 | i int; 138 | BEGIN 139 | -- Ensure the number of arguments is even 140 | IF array_length(args, 1) % 2 <> 0 THEN 141 | RAISE EXCEPTION 'Arguments must be provided in key-value pairs'; 142 | END IF; 143 | 144 | -- Iterate over the arguments two at a time 145 | FOR i IN 1..array_length(args, 1) BY 2 LOOP 146 | headers := array_append(headers, http_header(args[i], args[i+1])); 147 | END LOOP; 148 | 149 | RETURN headers; 150 | END; 151 | $$ 152 | LANGUAGE 'plpgsql' 153 | IMMUTABLE STRICT; 154 | -------------------------------------------------------------------------------- /http.c: -------------------------------------------------------------------------------- 1 | /*********************************************************************** 2 | * 3 | * Project: PgSQL HTTP 4 | * Purpose: Main file. 5 | * 6 | *********************************************************************** 7 | * Copyright 2025 Paul Ramsey 8 | * 9 | * Permission is hereby granted, free of charge, to any person obtaining a 10 | * copy of this software and associated documentation files (the 11 | * "Software"), to deal in the Software without restriction, including 12 | * without limitation the rights to use, copy, modify, merge, publish, 13 | * distribute, sublicense, and/or sell copies of the Software, and to 14 | * permit persons to whom the Software is furnished to do so, subject to 15 | * the following conditions: 16 | * 17 | * The above copyright notice and this permission notice shall be included 18 | * in all copies or substantial portions of the Software. 19 | * 20 | * THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS 21 | * OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 22 | * MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. 23 | * IN NO EVENT SHALL THE AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY 24 | * CLAIM, DAMAGES OR OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, 25 | * TORT OR OTHERWISE, ARISING FROM, OUT OF OR IN CONNECTION WITH THE 26 | * SOFTWARE OR THE USE OR OTHER DEALINGS IN THE SOFTWARE. 27 | * 28 | ***********************************************************************/ 29 | 30 | /* Constants */ 31 | #define HTTP_VERSION "1.7" 32 | #define HTTP_ENCODING "gzip" 33 | #define CURL_MIN_VERSION 0x071400 /* 7.20.0 */ 34 | 35 | /* System */ 36 | #include 37 | #include 38 | #include 39 | #include /* INT_MAX */ 40 | #include /* SIGINT */ 41 | 42 | /* PostgreSQL */ 43 | #include 44 | #include 45 | #include 46 | #include 47 | #include 48 | #include 49 | #include 50 | #include 51 | #include 52 | #include 53 | #include 54 | #include 55 | #include 56 | #include 57 | #include 58 | #include 59 | #include 60 | #include 61 | #include 62 | #include 63 | #include 64 | #include 65 | #include 66 | #include 67 | #include 68 | 69 | #if PG_VERSION_NUM >= 90300 70 | # include 71 | #endif 72 | 73 | #if PG_VERSION_NUM >= 100000 74 | # include 75 | #endif 76 | 77 | #if PG_VERSION_NUM >= 120000 78 | # include 79 | #else 80 | # define table_open(rel, lock) heap_open((rel), (lock)) 81 | # define table_close(rel, lock) heap_close((rel), (lock)) 82 | #endif 83 | 84 | #if PG_VERSION_NUM < 110000 85 | #define PG_GETARG_JSONB_P(x) DatumGetJsonb(PG_GETARG_DATUM(x)) 86 | #endif 87 | 88 | /* CURL */ 89 | #include 90 | 91 | /* Set up PgSQL */ 92 | PG_MODULE_MAGIC; 93 | 94 | /* HTTP request methods we support */ 95 | typedef enum { 96 | HTTP_GET, 97 | HTTP_POST, 98 | HTTP_DELETE, 99 | HTTP_PUT, 100 | HTTP_HEAD, 101 | HTTP_PATCH, 102 | HTTP_UNKNOWN 103 | } http_method; 104 | 105 | /* Components (and postitions) of the http_request tuple type */ 106 | enum { 107 | REQ_METHOD = 0, 108 | REQ_URI = 1, 109 | REQ_HEADERS = 2, 110 | REQ_CONTENT_TYPE = 3, 111 | REQ_CONTENT = 4 112 | } http_request_type; 113 | 114 | /* Components (and postitions) of the http_response tuple type */ 115 | enum { 116 | RESP_STATUS = 0, 117 | RESP_CONTENT_TYPE = 1, 118 | RESP_HEADERS = 2, 119 | RESP_CONTENT = 3 120 | } http_response_type; 121 | 122 | /* Components (and postitions) of the http_header tuple type */ 123 | enum { 124 | HEADER_FIELD = 0, 125 | HEADER_VALUE = 1 126 | } http_header_type; 127 | 128 | /* 129 | * String/Long for strings and numbers, blob only for 130 | * CURLOPT_SSLKEY_BLOB and CURLOPT_SSLCERT_BLOB 131 | */ 132 | typedef enum { 133 | CURLOPT_STRING, 134 | CURLOPT_LONG, 135 | CURLOPT_BLOB 136 | } http_curlopt_type; 137 | 138 | /* CURLOPT string/enum value mapping */ 139 | typedef struct { 140 | CURLoption curlopt; 141 | http_curlopt_type curlopt_type; 142 | bool superuser_only; 143 | char *curlopt_str; 144 | char *curlopt_val; 145 | char *curlopt_guc; 146 | } http_curlopt; 147 | 148 | 149 | /* CURLOPT values we allow user to set at run-time */ 150 | /* Be careful adding these, as they can be a security risk */ 151 | static http_curlopt settable_curlopts[] = { 152 | { CURLOPT_CAINFO, CURLOPT_STRING, false, "CURLOPT_CAINFO", NULL, NULL }, 153 | { CURLOPT_TIMEOUT, CURLOPT_LONG, false, "CURLOPT_TIMEOUT", NULL, NULL }, 154 | { CURLOPT_TIMEOUT_MS, CURLOPT_LONG, false, "CURLOPT_TIMEOUT_MS", NULL, NULL }, 155 | { CURLOPT_CONNECTTIMEOUT, CURLOPT_LONG, false, "CURLOPT_CONNECTTIMEOUT", NULL, NULL }, 156 | { CURLOPT_CONNECTTIMEOUT_MS, CURLOPT_LONG, false, "CURLOPT_CONNECTTIMEOUT_MS", NULL, NULL }, 157 | { CURLOPT_USERAGENT, CURLOPT_STRING, false, "CURLOPT_USERAGENT", NULL, NULL }, 158 | { CURLOPT_USERPWD, CURLOPT_STRING, false, "CURLOPT_USERPWD", NULL, NULL }, 159 | { CURLOPT_IPRESOLVE, CURLOPT_LONG, false, "CURLOPT_IPRESOLVE", NULL, NULL }, 160 | #if LIBCURL_VERSION_NUM >= 0x070903 /* 7.9.3 */ 161 | { CURLOPT_SSLCERTTYPE, CURLOPT_STRING, false, "CURLOPT_SSLCERTTYPE", NULL, NULL }, 162 | #endif 163 | #if LIBCURL_VERSION_NUM >= 0x070e01 /* 7.14.1 */ 164 | { CURLOPT_PROXY, CURLOPT_STRING, false, "CURLOPT_PROXY", NULL, NULL }, 165 | { CURLOPT_PROXYPORT, CURLOPT_LONG, false, "CURLOPT_PROXYPORT", NULL, NULL }, 166 | #endif 167 | #if LIBCURL_VERSION_NUM >= 0x071301 /* 7.19.1 */ 168 | { CURLOPT_PROXYUSERNAME, CURLOPT_STRING, false, "CURLOPT_PROXYUSERNAME", NULL, NULL }, 169 | { CURLOPT_PROXYPASSWORD, CURLOPT_STRING, false, "CURLOPT_PROXYPASSWORD", NULL, NULL }, 170 | #endif 171 | #if LIBCURL_VERSION_NUM >= 0x071504 /* 7.21.4 */ 172 | { CURLOPT_TLSAUTH_USERNAME, CURLOPT_STRING, false, "CURLOPT_TLSAUTH_USERNAME", NULL, NULL }, 173 | { CURLOPT_TLSAUTH_PASSWORD, CURLOPT_STRING, false, "CURLOPT_TLSAUTH_PASSWORD", NULL, NULL }, 174 | { CURLOPT_TLSAUTH_TYPE, CURLOPT_STRING, false, "CURLOPT_TLSAUTH_TYPE", NULL, NULL }, 175 | #endif 176 | #if LIBCURL_VERSION_NUM >= 0x071800 /* 7.24.0 */ 177 | { CURLOPT_DNS_SERVERS, CURLOPT_STRING, false, "CURLOPT_DNS_SERVERS", NULL, NULL }, 178 | #endif 179 | #if LIBCURL_VERSION_NUM >= 0x071900 /* 7.25.0 */ 180 | { CURLOPT_TCP_KEEPALIVE, CURLOPT_LONG, false, "CURLOPT_TCP_KEEPALIVE", NULL, NULL }, 181 | { CURLOPT_TCP_KEEPIDLE, CURLOPT_LONG, false, "CURLOPT_TCP_KEEPIDLE", NULL, NULL }, 182 | #endif 183 | #if LIBCURL_VERSION_NUM >= 0x072500 /* 7.37.0 */ 184 | { CURLOPT_SSL_VERIFYHOST, CURLOPT_LONG, false, "CURLOPT_SSL_VERIFYHOST", NULL, NULL }, 185 | { CURLOPT_SSL_VERIFYPEER, CURLOPT_LONG, false, "CURLOPT_SSL_VERIFYPEER", NULL, NULL }, 186 | #endif 187 | { CURLOPT_SSLCERT, CURLOPT_STRING, false, "CURLOPT_SSLCERT", NULL, NULL }, 188 | { CURLOPT_SSLKEY, CURLOPT_STRING, false, "CURLOPT_SSLKEY", NULL, NULL }, 189 | #if LIBCURL_VERSION_NUM >= 0x073400 /* 7.52.0 */ 190 | { CURLOPT_PRE_PROXY, CURLOPT_STRING, false, "CURLOPT_PRE_PROXY", NULL, NULL }, 191 | { CURLOPT_PROXY_TLSAUTH_USERNAME, CURLOPT_STRING, false, "CURLOPT_PROXY_CAINFO", NULL, NULL }, 192 | { CURLOPT_PROXY_TLSAUTH_USERNAME, CURLOPT_STRING, false, "CURLOPT_PROXY_TLSAUTH_USERNAME", NULL, NULL }, 193 | { CURLOPT_PROXY_TLSAUTH_PASSWORD, CURLOPT_STRING, false, "CURLOPT_PROXY_TLSAUTH_PASSWORD", NULL, NULL }, 194 | { CURLOPT_PROXY_TLSAUTH_TYPE, CURLOPT_STRING, false, "CURLOPT_PROXY_TLSAUTH_TYPE", NULL, NULL }, 195 | #endif 196 | #if LIBCURL_VERSION_NUM >= 0x074700 /* 7.71.0 */ 197 | { CURLOPT_SSLKEY_BLOB, CURLOPT_BLOB, false, "CURLOPT_SSLKEY_BLOB", NULL, NULL }, 198 | { CURLOPT_SSLCERT_BLOB, CURLOPT_BLOB, false, "CURLOPT_SSLCERT_BLOB", NULL, NULL }, 199 | #endif 200 | { 0, 0, false, NULL, NULL, NULL } /* Array null terminator */ 201 | }; 202 | 203 | 204 | /* Function signatures */ 205 | void _PG_init(void); 206 | void _PG_fini(void); 207 | static size_t http_writeback(void *contents, size_t size, size_t nmemb, void *userp); 208 | static size_t http_readback(void *buffer, size_t size, size_t nitems, void *instream); 209 | 210 | /* Global variables */ 211 | CURL * g_http_handle = NULL; 212 | 213 | /* 214 | * Interrupt support is dependent on CURLOPT_XFERINFOFUNCTION which 215 | * is only available from 7.39.0 and up 216 | */ 217 | #if LIBCURL_VERSION_NUM >= 0x072700 /* 7.39.0 */ 218 | 219 | /* 220 | * To support request interruption, we have libcurl run the progress meter 221 | * callback frequently, and here we watch to see if PgSQL has flipped 222 | * the global QueryCancelPending || ProcDiePending flags. 223 | * Curl should then return CURLE_ABORTED_BY_CALLBACK 224 | * to the curl_easy_perform() call. 225 | */ 226 | static int 227 | http_progress_callback(void *clientp, curl_off_t dltotal, curl_off_t dlnow, curl_off_t ultotal, curl_off_t ulnow) 228 | { 229 | #ifdef WIN32 230 | if (UNBLOCKED_SIGNAL_QUEUE()) 231 | pgwin32_dispatch_queued_signals(); 232 | #endif 233 | /* Check the PgSQL global flags */ 234 | return QueryCancelPending || ProcDiePending; 235 | } 236 | 237 | #endif /* 7.39.0 */ 238 | 239 | #undef HTTP_MEM_CALLBACKS 240 | #ifdef HTTP_MEM_CALLBACKS 241 | static void * 242 | http_calloc(size_t a, size_t b) 243 | { 244 | if (a>0 && b>0) 245 | return palloc0(a*b); 246 | else 247 | return NULL; 248 | } 249 | 250 | static void 251 | http_free(void *a) 252 | { 253 | if (a) 254 | pfree(a); 255 | } 256 | 257 | static void * 258 | http_realloc(void *a, size_t sz) 259 | { 260 | if (a && sz) 261 | return repalloc(a, sz); 262 | else if (sz) 263 | return palloc(sz); 264 | else 265 | return a; 266 | } 267 | 268 | static void * 269 | http_malloc(size_t sz) 270 | { 271 | return sz ? palloc(sz) : NULL; 272 | } 273 | #endif 274 | 275 | 276 | static char * 277 | http_strtolower(const char *input) 278 | { 279 | char *ptr, *output; 280 | if (input == NULL) 281 | return NULL; 282 | 283 | /* Allocate memory for the output string */ 284 | output = palloc(strlen(input) + 1); 285 | ptr = output; 286 | 287 | while (*input) 288 | { 289 | *ptr++ = tolower((unsigned char) *input); 290 | input++; 291 | } 292 | 293 | *ptr = '\0'; // Null-terminate the string 294 | return output; 295 | } 296 | 297 | 298 | #if PG_VERSION_NUM < 160000 299 | static void * 300 | guc_malloc(int elevel, size_t size) 301 | { 302 | void *data; 303 | 304 | /* Avoid unportable behavior of malloc(0) */ 305 | if (size == 0) 306 | size = 1; 307 | data = malloc(size); 308 | if (data == NULL) 309 | ereport(elevel, 310 | (errcode(ERRCODE_OUT_OF_MEMORY), 311 | errmsg("out of memory"))); 312 | return data; 313 | } 314 | 315 | static char * 316 | guc_strdup(int elevel, const char *src) 317 | { 318 | size_t len = strlen(src) + 1; 319 | char *dup = guc_malloc(elevel, len); 320 | memcpy(dup, src, len); 321 | return dup; 322 | } 323 | 324 | static void 325 | guc_free(void *ptr) 326 | { 327 | free(ptr); 328 | } 329 | #endif 330 | 331 | 332 | static void 333 | http_guc_init_opt(http_curlopt *opt) 334 | { 335 | char *opt_name_lower = http_strtolower(opt->curlopt_str); 336 | char *opt_name = psprintf("http.%s", opt_name_lower); 337 | 338 | const char *url_tmpl = "https://curl.se/libcurl/c/%s.html"; 339 | char *opt_url = psprintf(url_tmpl, opt->curlopt_str); 340 | opt->curlopt_guc = guc_strdup(ERROR, opt_name); 341 | 342 | DefineCustomStringVariable( 343 | opt_name, // const char *name 344 | guc_strdup(ERROR, opt_url), // const char *short_desc 345 | NULL, // const char *long_desc 346 | &(opt->curlopt_val), // char **valueAddr 347 | NULL, // const char *bootValue 348 | opt->superuser_only ? PGC_SUSET : PGC_USERSET, // GucContext context 349 | 0, // int flags 350 | NULL, // GucStringCheckHook check_hook 351 | NULL, // GucStringAssignHook assign_hook 352 | NULL // GucShowHook show_hook 353 | ); 354 | 355 | pfree(opt_name_lower); 356 | pfree(opt_name); 357 | pfree(opt_url); 358 | 359 | /* 360 | * Backwards compatibility, retain the old GUC 361 | * http.keepalive name for now. 362 | */ 363 | if (opt->curlopt == CURLOPT_TCP_KEEPALIVE) 364 | { 365 | DefineCustomStringVariable( 366 | "http.keepalive", 367 | guc_strdup(ERROR, "https://curl.se/libcurl/c/CURLOPT_TCP_KEEPALIVE.html"), 368 | NULL, 369 | &(opt->curlopt_val), 370 | NULL, 371 | opt->superuser_only ? PGC_SUSET : PGC_USERSET, 372 | 0, NULL, NULL, NULL 373 | ); 374 | } 375 | 376 | /* 377 | * Backwards compatibility, retain the old GUC 378 | * http.timeout_msec name for now. 379 | */ 380 | if (opt->curlopt == CURLOPT_TIMEOUT_MS) 381 | { 382 | DefineCustomStringVariable( 383 | "http.timeout_msec", 384 | guc_strdup(ERROR, "https://curl.se/libcurl/c/CURLOPT_TIMEOUT_MS.html"), 385 | NULL, 386 | &(opt->curlopt_val), 387 | NULL, 388 | opt->superuser_only ? PGC_SUSET : PGC_USERSET, 389 | 0, NULL, NULL, NULL 390 | ); 391 | } 392 | } 393 | 394 | static void 395 | http_guc_init() 396 | { 397 | http_curlopt *opt = settable_curlopts; 398 | while (opt->curlopt) 399 | { 400 | http_guc_init_opt(opt); 401 | opt++; 402 | } 403 | } 404 | 405 | 406 | /* Startup */ 407 | void _PG_init(void) 408 | { 409 | 410 | /* 411 | * Initialize the DefineCustomStringVariable GUC 412 | * functions to allow "SET http.curlopt_var = value" 413 | * to manipulate CURL options. 414 | */ 415 | http_guc_init(); 416 | 417 | #ifdef HTTP_MEM_CALLBACKS 418 | /* 419 | * Use PgSQL memory management in Curl 420 | * Warning, https://curl.se/libcurl/c/curl_global_init_mem.html 421 | * notes "If you are using libcurl from multiple threads or libcurl 422 | * was built with the threaded resolver option then the callback 423 | * functions must be thread safe." PgSQL isn't multi-threaded, 424 | * but we have no control over whether the "threaded resolver" is 425 | * in use. We may need a semaphor to ensure our callbacks are 426 | * accessed sequentially only. 427 | */ 428 | curl_global_init_mem(CURL_GLOBAL_ALL, http_malloc, http_free, http_realloc, pstrdup, http_calloc); 429 | #else 430 | /* Set up Curl! */ 431 | curl_global_init(CURL_GLOBAL_ALL); 432 | #endif 433 | 434 | 435 | } 436 | 437 | /* Tear-down */ 438 | void _PG_fini(void) 439 | { 440 | if (g_http_handle) 441 | { 442 | curl_easy_cleanup(g_http_handle); 443 | g_http_handle = NULL; 444 | } 445 | 446 | curl_global_cleanup(); 447 | elog(NOTICE, "Goodbye from HTTP %s", HTTP_VERSION); 448 | } 449 | 450 | /** 451 | * This function is passed into CURL as the CURLOPT_WRITEFUNCTION, 452 | * this allows the return values to be held in memory, in our case in a string. 453 | */ 454 | static size_t 455 | http_writeback(void *contents, size_t size, size_t nmemb, void *userp) 456 | { 457 | size_t realsize = size * nmemb; 458 | StringInfo si = (StringInfo)userp; 459 | appendBinaryStringInfo(si, (const char*)contents, (int)realsize); 460 | return realsize; 461 | } 462 | 463 | /** 464 | * This function is passed into CURL as the CURLOPT_READFUNCTION, 465 | * this allows the PUT operation to read the data it needs. We 466 | * pass a StringInfo as our input, and per the callback contract 467 | * return the number of bytes read at each call. 468 | */ 469 | static size_t 470 | http_readback(void *buffer, size_t size, size_t nitems, void *instream) 471 | { 472 | size_t reqsize = size * nitems; 473 | StringInfo si = (StringInfo)instream; 474 | size_t remaining = si->len - si->cursor; 475 | size_t readsize = Min(reqsize, remaining); 476 | memcpy(buffer, si->data + si->cursor, readsize); 477 | si->cursor += readsize; 478 | return readsize; 479 | } 480 | 481 | static void 482 | http_error(CURLcode err, const char *error_buffer) 483 | { 484 | if ( strlen(error_buffer) > 0 ) 485 | ereport(ERROR, (errmsg("%s", error_buffer))); 486 | else 487 | ereport(ERROR, (errmsg("%s", curl_easy_strerror(err)))); 488 | } 489 | 490 | /* Utility macro to try a setopt and catch an error */ 491 | #define CURL_SETOPT(handle, opt, value) do { \ 492 | err = curl_easy_setopt((handle), (opt), (value)); \ 493 | if ( err != CURLE_OK ) \ 494 | { \ 495 | http_error(err, http_error_buffer); \ 496 | PG_RETURN_NULL(); \ 497 | } \ 498 | } while (0); 499 | 500 | 501 | /** 502 | * Convert a request type string into the appropriate enumeration value. 503 | */ 504 | static http_method 505 | request_type(const char *method) 506 | { 507 | if ( strcasecmp(method, "GET") == 0 ) 508 | return HTTP_GET; 509 | else if ( strcasecmp(method, "POST") == 0 ) 510 | return HTTP_POST; 511 | else if ( strcasecmp(method, "PUT") == 0 ) 512 | return HTTP_PUT; 513 | else if ( strcasecmp(method, "DELETE") == 0 ) 514 | return HTTP_DELETE; 515 | else if ( strcasecmp(method, "HEAD") == 0 ) 516 | return HTTP_HEAD; 517 | else if ( strcasecmp(method, "PATCH") == 0 ) 518 | return HTTP_PATCH; 519 | else 520 | return HTTP_UNKNOWN; 521 | } 522 | 523 | /** 524 | * Given a field name and value, output a http_header tuple. 525 | */ 526 | static Datum 527 | header_tuple(TupleDesc header_tuple_desc, const char *field, const char *value) 528 | { 529 | HeapTuple header_tuple; 530 | int ncolumns; 531 | Datum *header_values; 532 | bool *header_nulls; 533 | 534 | /* Prepare our return object */ 535 | ncolumns = header_tuple_desc->natts; 536 | header_values = palloc0(sizeof(Datum)*ncolumns); 537 | header_nulls = palloc0(sizeof(bool)*ncolumns); 538 | 539 | header_values[HEADER_FIELD] = CStringGetTextDatum(field); 540 | header_nulls[HEADER_FIELD] = false; 541 | header_values[HEADER_VALUE] = CStringGetTextDatum(value); 542 | header_nulls[HEADER_VALUE] = false; 543 | 544 | /* Build up a tuple from values/nulls lists */ 545 | header_tuple = heap_form_tuple(header_tuple_desc, header_values, header_nulls); 546 | return HeapTupleGetDatum(header_tuple); 547 | } 548 | 549 | /** 550 | * Our own implementation of strcasestr. 551 | */ 552 | static char * 553 | http_strcasestr(const char *s, const char *find) 554 | { 555 | char c, sc; 556 | size_t len; 557 | 558 | if ((c = *find++) != 0) 559 | { 560 | c = tolower((unsigned char)c); 561 | len = strlen(find); 562 | do 563 | { 564 | do 565 | { 566 | if ((sc = *s++) == 0) 567 | return (NULL); 568 | } 569 | while ((char)tolower((unsigned char)sc) != c); 570 | } 571 | while (strncasecmp(s, find, len) != 0); 572 | s--; 573 | } 574 | return ((char *)s); 575 | } 576 | 577 | /** 578 | * Quick and dirty, remove all \r from a StringInfo. 579 | */ 580 | static void 581 | string_info_remove_cr(StringInfo si) 582 | { 583 | int i = 0, j = 0; 584 | while ( si->data[i] ) 585 | { 586 | if ( si->data[i] != '\r' ) 587 | si->data[j++] = si->data[i++]; 588 | else 589 | i++; 590 | } 591 | si->data[j] = '\0'; 592 | si->len -= i-j; 593 | return; 594 | } 595 | 596 | /** 597 | * Add an array of http_header tuples into a Curl string list. 598 | */ 599 | static struct curl_slist * 600 | header_array_to_slist(ArrayType *array, struct curl_slist *headers) 601 | { 602 | ArrayIterator iterator; 603 | Datum value; 604 | bool isnull; 605 | 606 | #if PG_VERSION_NUM >= 90500 607 | iterator = array_create_iterator(array, 0, NULL); 608 | #else 609 | iterator = array_create_iterator(array, 0); 610 | #endif 611 | 612 | while (array_iterate(iterator, &value, &isnull)) 613 | { 614 | HeapTupleHeader rec; 615 | HeapTupleData tuple; 616 | Oid tup_type; 617 | int32 tup_typmod, ncolumns; 618 | TupleDesc tup_desc; 619 | size_t tup_len; 620 | Datum *values; 621 | bool *nulls; 622 | 623 | /* Skip null array items */ 624 | if ( isnull ) 625 | continue; 626 | 627 | rec = DatumGetHeapTupleHeader(value); 628 | tup_type = HeapTupleHeaderGetTypeId(rec); 629 | tup_typmod = HeapTupleHeaderGetTypMod(rec); 630 | tup_len = HeapTupleHeaderGetDatumLength(rec); 631 | tup_desc = lookup_rowtype_tupdesc(tup_type, tup_typmod); 632 | ncolumns = tup_desc->natts; 633 | 634 | /* Prepare for values / nulls to hold the data */ 635 | values = (Datum *) palloc0(ncolumns * sizeof(Datum)); 636 | nulls = (bool *) palloc0(ncolumns * sizeof(bool)); 637 | 638 | /* Build a temporary HeapTuple control structure */ 639 | tuple.t_len = tup_len; 640 | ItemPointerSetInvalid(&(tuple.t_self)); 641 | tuple.t_tableOid = InvalidOid; 642 | tuple.t_data = rec; 643 | 644 | /* Break down the tuple into values/nulls lists */ 645 | heap_deform_tuple(&tuple, tup_desc, values, nulls); 646 | 647 | /* Convert the data into a header */ 648 | /* TODO: Ensure the header list is unique? Or leave that to the */ 649 | /* server to deal with. */ 650 | if ( ! nulls[HEADER_FIELD] ) 651 | { 652 | size_t total_len = 0; 653 | char *buffer = NULL; 654 | char *header_val; 655 | char *header_fld = TextDatumGetCString(values[HEADER_FIELD]); 656 | 657 | /* Don't process "content-type" in the optional headers */ 658 | if ( strlen(header_fld) <= 0 || strncasecmp(header_fld, "Content-Type", 12) == 0 ) 659 | { 660 | elog(NOTICE, "'Content-Type' is not supported as an optional header"); 661 | continue; 662 | } 663 | 664 | if ( nulls[HEADER_VALUE] ) 665 | header_val = pstrdup(""); 666 | else 667 | header_val = TextDatumGetCString(values[HEADER_VALUE]); 668 | total_len = strlen(header_val) + strlen(header_fld) + sizeof(char) + sizeof(": "); 669 | buffer = palloc(total_len); 670 | if (buffer) 671 | { 672 | snprintf(buffer, total_len, "%s: %s", header_fld, header_val); 673 | elog(DEBUG2, "pgsql-http: optional request header '%s'", buffer); 674 | headers = curl_slist_append(headers, buffer); 675 | pfree(buffer); 676 | } 677 | else 678 | { 679 | elog(ERROR, "pgsql-http: palloc(%zu) failure", total_len); 680 | } 681 | pfree(header_fld); 682 | pfree(header_val); 683 | } 684 | 685 | /* Free all the temporary structures */ 686 | ReleaseTupleDesc(tup_desc); 687 | pfree(values); 688 | pfree(nulls); 689 | } 690 | array_free_iterator(iterator); 691 | 692 | return headers; 693 | } 694 | /** 695 | * This function is now exposed in PG16 and above 696 | * so no need to redefine it for PG16 and above 697 | */ 698 | #if PG_VERSION_NUM < 160000 699 | /** 700 | * Look up the namespace the extension is installed in 701 | */ 702 | static Oid 703 | get_extension_schema(Oid ext_oid) 704 | { 705 | Oid result; 706 | SysScanDesc scandesc; 707 | HeapTuple tuple; 708 | ScanKeyData entry[1]; 709 | #if PG_VERSION_NUM >= 120000 710 | Oid pg_extension_oid = Anum_pg_extension_oid; 711 | #else 712 | Oid pg_extension_oid = ObjectIdAttributeNumber; 713 | #endif 714 | Relation rel = table_open(ExtensionRelationId, AccessShareLock); 715 | 716 | ScanKeyInit(&entry[0], 717 | pg_extension_oid, 718 | BTEqualStrategyNumber, F_OIDEQ, 719 | ObjectIdGetDatum(ext_oid)); 720 | 721 | scandesc = systable_beginscan(rel, ExtensionOidIndexId, true, 722 | NULL, 1, entry); 723 | 724 | tuple = systable_getnext(scandesc); 725 | 726 | /* We assume that there can be at most one matching tuple */ 727 | if (HeapTupleIsValid(tuple)) 728 | result = ((Form_pg_extension) GETSTRUCT(tuple))->extnamespace; 729 | else 730 | result = InvalidOid; 731 | 732 | systable_endscan(scandesc); 733 | 734 | table_close(rel, AccessShareLock); 735 | 736 | return result; 737 | } 738 | #endif 739 | 740 | /** 741 | * Look up the tuple description for a extension-defined type, 742 | * avoiding the pitfalls of using relations that are not part 743 | * of the extension, but share the same name as the relation 744 | * of interest. 745 | */ 746 | static TupleDesc 747 | typname_get_tupledesc(const char *extname, const char *typname) 748 | { 749 | Oid extoid = get_extension_oid(extname, true); 750 | Oid extschemaoid; 751 | Oid typoid; 752 | 753 | if ( ! OidIsValid(extoid) ) 754 | elog(ERROR, "could not lookup '%s' extension oid", extname); 755 | 756 | extschemaoid = get_extension_schema(extoid); 757 | 758 | #if PG_VERSION_NUM >= 120000 759 | typoid = GetSysCacheOid2(TYPENAMENSP, Anum_pg_type_oid, 760 | PointerGetDatum(typname), 761 | ObjectIdGetDatum(extschemaoid)); 762 | #else 763 | typoid = GetSysCacheOid2(TYPENAMENSP, 764 | PointerGetDatum(typname), 765 | ObjectIdGetDatum(extschemaoid)); 766 | #endif 767 | 768 | if ( OidIsValid(typoid) ) 769 | { 770 | // Oid typ_oid = get_typ_typrelid(rel_oid); 771 | Oid relextoid = getExtensionOfObject(TypeRelationId, typoid); 772 | if ( relextoid == extoid ) 773 | { 774 | return TypeGetTupleDesc(typoid, NIL); 775 | } 776 | } 777 | 778 | elog(ERROR, "could not lookup '%s' tuple desc", typname); 779 | } 780 | 781 | 782 | #define RVSZ 8192 /* Max length of header element */ 783 | 784 | /** 785 | * Convert a string of headers separated by newlines/CRs into an 786 | * array of http_header tuples. 787 | */ 788 | static ArrayType * 789 | header_string_to_array(StringInfo si) 790 | { 791 | /* Array building */ 792 | size_t arr_nelems = 0; 793 | size_t arr_elems_size = 8; 794 | Datum *arr_elems = palloc0(arr_elems_size*sizeof(Datum)); 795 | Oid elem_type; 796 | int16 elem_len; 797 | bool elem_byval; 798 | char elem_align; 799 | 800 | /* Header handling */ 801 | TupleDesc header_tuple_desc = NULL; 802 | 803 | /* Regex support */ 804 | const char *regex_pattern = "^([^ \t\r\n\v\f]+): ?([^ \t\r\n\v\f]+.*)$"; 805 | regex_t regex; 806 | regmatch_t pmatch[3]; 807 | int reti; 808 | char rv1[RVSZ]; 809 | char rv2[RVSZ]; 810 | 811 | /* Compile the regular expression */ 812 | reti = regcomp(®ex, regex_pattern, REG_ICASE | REG_EXTENDED | REG_NEWLINE ); 813 | if ( reti ) 814 | elog(ERROR, "Unable to compile regex pattern '%s'", regex_pattern); 815 | 816 | /* Lookup the tuple defn */ 817 | header_tuple_desc = typname_get_tupledesc("http", "http_header"); 818 | 819 | /* Prepare array building metadata */ 820 | elem_type = header_tuple_desc->tdtypeid; 821 | get_typlenbyvalalign(elem_type, &elem_len, &elem_byval, &elem_align); 822 | 823 | /* Loop through string, matching regex pattern */ 824 | si->cursor = 0; 825 | while ( ! regexec(®ex, si->data+si->cursor, 3, pmatch, 0) ) 826 | { 827 | /* Read the regex match results */ 828 | int eo0 = pmatch[0].rm_eo; 829 | int so1 = pmatch[1].rm_so; 830 | int eo1 = pmatch[1].rm_eo; 831 | int so2 = pmatch[2].rm_so; 832 | int eo2 = pmatch[2].rm_eo; 833 | 834 | /* Copy the matched portions out of the string */ 835 | memcpy(rv1, si->data+si->cursor+so1, Min(eo1-so1, RVSZ)); 836 | rv1[eo1-so1] = '\0'; 837 | memcpy(rv2, si->data+si->cursor+so2, Min(eo2-so2, RVSZ)); 838 | rv2[eo2-so2] = '\0'; 839 | 840 | /* Move forward for next match */ 841 | si->cursor += eo0; 842 | 843 | /* Increase elements array size if necessary */ 844 | if ( arr_nelems >= arr_elems_size ) 845 | { 846 | arr_elems_size *= 2; 847 | arr_elems = repalloc(arr_elems, arr_elems_size*sizeof(Datum)); 848 | } 849 | arr_elems[arr_nelems] = header_tuple(header_tuple_desc, rv1, rv2); 850 | arr_nelems++; 851 | } 852 | 853 | regfree(®ex); 854 | ReleaseTupleDesc(header_tuple_desc); 855 | return construct_array(arr_elems, arr_nelems, elem_type, elem_len, elem_byval, elem_align); 856 | } 857 | 858 | /* Check/log version info */ 859 | static void 860 | http_check_curl_version(const curl_version_info_data *version_info) 861 | { 862 | elog(DEBUG2, "pgsql-http: curl version %s", version_info->version); 863 | elog(DEBUG2, "pgsql-http: curl version number 0x%x", version_info->version_num); 864 | elog(DEBUG2, "pgsql-http: ssl version %s", version_info->ssl_version); 865 | 866 | if ( version_info->version_num < CURL_MIN_VERSION ) 867 | { 868 | elog(ERROR, "pgsql-http requires Curl version 0.7.20 or higher"); 869 | } 870 | } 871 | 872 | 873 | static bool 874 | curlopt_is_set(CURLoption curlopt) 875 | { 876 | http_curlopt *opt = settable_curlopts; 877 | while (opt->curlopt) 878 | { 879 | if (opt->curlopt == curlopt && opt->curlopt_val) 880 | return true; 881 | opt++; 882 | } 883 | return false; 884 | } 885 | 886 | 887 | static bool 888 | set_curlopt(CURL* handle, const http_curlopt *opt) 889 | { 890 | CURLcode err = CURLE_OK; 891 | char http_error_buffer[CURL_ERROR_SIZE] = "\0"; 892 | 893 | memset(http_error_buffer, 0, sizeof(http_error_buffer)); 894 | 895 | /* Argument is a string */ 896 | if (opt->curlopt_type == CURLOPT_STRING) 897 | { 898 | err = curl_easy_setopt(handle, opt->curlopt, opt->curlopt_val); 899 | elog(DEBUG2, "pgsql-http: set '%s' to value '%s', return value = %d", opt->curlopt_guc, opt->curlopt_val, err); 900 | } 901 | /* Argument is a long */ 902 | else if (opt->curlopt_type == CURLOPT_LONG) 903 | { 904 | long value_long; 905 | errno = 0; 906 | value_long = strtol(opt->curlopt_val, NULL, 10); 907 | if ( errno == EINVAL || errno == ERANGE ) 908 | elog(ERROR, "invalid integer provided for '%s'", opt->curlopt_guc); 909 | 910 | err = curl_easy_setopt(handle, opt->curlopt, value_long); 911 | elog(DEBUG2, "pgsql-http: set '%s' to value '%ld', return value = %d", opt->curlopt_guc, value_long, err); 912 | } 913 | /* Only used for CURLOPT_SSLKEY_BLOB and CURLOPT_SSLCERT_BLOB */ 914 | else if (opt->curlopt_type == CURLOPT_BLOB) 915 | { 916 | struct curl_blob blob; 917 | blob.len = strlen(opt->curlopt_val) + 1; 918 | blob.data = opt->curlopt_val; 919 | blob.flags = CURL_BLOB_COPY; 920 | 921 | err = curl_easy_setopt(handle, CURLOPT_SSLKEYTYPE, "PEM"); 922 | elog(DEBUG2, "pgsql-http: set 'CURLOPT_SSLKEYTYPE' to value 'PEM', return value = %d", err); 923 | 924 | err = curl_easy_setopt(handle, opt->curlopt, &blob); 925 | elog(DEBUG2, "pgsql-http: set '%s' to value '%s', return value = %d", opt->curlopt_guc, opt->curlopt_val, err); 926 | } 927 | else 928 | { 929 | /* Never get here */ 930 | elog(ERROR, "invalid curlopt_type, '%d'", opt->curlopt_type); 931 | } 932 | 933 | if ( err != CURLE_OK ) 934 | { 935 | http_error(err, http_error_buffer); 936 | return false; 937 | } 938 | return true; 939 | } 940 | 941 | /* Check/create the global CURL* handle */ 942 | static CURL * 943 | http_get_handle() 944 | { 945 | CURL *handle = g_http_handle; 946 | http_curlopt *opt = settable_curlopts; 947 | 948 | /* Initialize the global handle if needed */ 949 | if (!handle) 950 | { 951 | handle = curl_easy_init(); 952 | } 953 | /* Always reset because we are going to fill in the user */ 954 | /* set options down below */ 955 | else 956 | { 957 | curl_easy_reset(handle); 958 | } 959 | 960 | /* Always want a default fast (1 second) connection timeout */ 961 | /* User can over-ride with http_set_curlopt() if they wish */ 962 | curl_easy_setopt(handle, CURLOPT_CONNECTTIMEOUT_MS, 1000); 963 | curl_easy_setopt(handle, CURLOPT_TIMEOUT_MS, 5000); 964 | 965 | /* Set the user agent. If not set, use PG_VERSION as default */ 966 | curl_easy_setopt(handle, CURLOPT_USERAGENT, PG_VERSION_STR); 967 | 968 | if (!handle) 969 | ereport(ERROR, (errmsg("Unable to initialize CURL"))); 970 | 971 | /* Bring in any options the user has set this session */ 972 | while (opt->curlopt) 973 | { 974 | /* Option value is already set */ 975 | if (opt->curlopt_val) 976 | set_curlopt(handle, opt); 977 | opt++; 978 | } 979 | 980 | g_http_handle = handle; 981 | return handle; 982 | } 983 | 984 | 985 | /** 986 | * User-defined Curl option reset. 987 | */ 988 | Datum http_reset_curlopt(PG_FUNCTION_ARGS); 989 | PG_FUNCTION_INFO_V1(http_reset_curlopt); 990 | Datum http_reset_curlopt(PG_FUNCTION_ARGS) 991 | { 992 | http_curlopt *opt = settable_curlopts; 993 | /* Set up global HTTP handle */ 994 | CURL * handle = http_get_handle(); 995 | curl_easy_reset(handle); 996 | 997 | /* Clean out the settable_curlopts global cache */ 998 | while (opt->curlopt) 999 | { 1000 | if (opt->curlopt_val) guc_free(opt->curlopt_val); 1001 | opt->curlopt_val = NULL; 1002 | opt++; 1003 | } 1004 | 1005 | PG_RETURN_BOOL(true); 1006 | } 1007 | 1008 | Datum http_list_curlopt(PG_FUNCTION_ARGS); 1009 | PG_FUNCTION_INFO_V1(http_list_curlopt); 1010 | Datum http_list_curlopt(PG_FUNCTION_ARGS) 1011 | { 1012 | struct list_state { 1013 | size_t i; /* read position */ 1014 | }; 1015 | 1016 | MemoryContext oldcontext, newcontext; 1017 | FuncCallContext *funcctx; 1018 | struct list_state *state; 1019 | Datum vals[2]; 1020 | bool nulls[2]; 1021 | 1022 | if (SRF_IS_FIRSTCALL()) 1023 | { 1024 | funcctx = SRF_FIRSTCALL_INIT(); 1025 | newcontext = funcctx->multi_call_memory_ctx; 1026 | oldcontext = MemoryContextSwitchTo(newcontext); 1027 | state = palloc0(sizeof(*state)); 1028 | funcctx->user_fctx = state; 1029 | if(get_call_result_type(fcinfo, 0, &funcctx->tuple_desc) != TYPEFUNC_COMPOSITE) 1030 | ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 1031 | errmsg("composite-returning function called in context that cannot accept a composite"))); 1032 | 1033 | BlessTupleDesc(funcctx->tuple_desc); 1034 | MemoryContextSwitchTo(oldcontext); 1035 | } 1036 | 1037 | funcctx = SRF_PERCALL_SETUP(); 1038 | state = funcctx->user_fctx; 1039 | 1040 | while (1) 1041 | { 1042 | Datum result; 1043 | HeapTuple tuple; 1044 | text *option, *value; 1045 | http_curlopt *opt = settable_curlopts + state->i++; 1046 | if (!opt->curlopt_str) 1047 | break; 1048 | if (!opt->curlopt_val) 1049 | continue; 1050 | option = cstring_to_text(opt->curlopt_str); 1051 | value = cstring_to_text(opt->curlopt_val); 1052 | vals[0] = PointerGetDatum(option); 1053 | vals[1] = PointerGetDatum(value); 1054 | nulls[0] = nulls[1] = 0; 1055 | tuple = heap_form_tuple(funcctx->tuple_desc, vals, nulls); 1056 | result = HeapTupleGetDatum(tuple); 1057 | SRF_RETURN_NEXT(funcctx, result); 1058 | } 1059 | 1060 | SRF_RETURN_DONE(funcctx); 1061 | } 1062 | 1063 | /** 1064 | * User-defined Curl option handling. 1065 | */ 1066 | Datum http_set_curlopt(PG_FUNCTION_ARGS); 1067 | PG_FUNCTION_INFO_V1(http_set_curlopt); 1068 | Datum http_set_curlopt(PG_FUNCTION_ARGS) 1069 | { 1070 | char *curlopt, *value; 1071 | text *curlopt_txt, *value_txt; 1072 | CURL *handle; 1073 | http_curlopt *opt = settable_curlopts; 1074 | 1075 | /* Version check */ 1076 | http_check_curl_version(curl_version_info(CURLVERSION_NOW)); 1077 | 1078 | /* We cannot handle null arguments */ 1079 | if ( PG_ARGISNULL(0) || PG_ARGISNULL(1) ) 1080 | PG_RETURN_BOOL(false); 1081 | 1082 | /* Set up global HTTP handle */ 1083 | handle = http_get_handle(); 1084 | 1085 | /* Read arguments */ 1086 | curlopt_txt = PG_GETARG_TEXT_P(0); 1087 | value_txt = PG_GETARG_TEXT_P(1); 1088 | curlopt = text_to_cstring(curlopt_txt); 1089 | value = text_to_cstring(value_txt); 1090 | 1091 | while (opt->curlopt) 1092 | { 1093 | if (strcasecmp(opt->curlopt_str, curlopt) == 0) 1094 | { 1095 | if (opt->curlopt_val) guc_free(opt->curlopt_val); 1096 | opt->curlopt_val = guc_strdup(ERROR, value); 1097 | PG_RETURN_BOOL(set_curlopt(handle, opt)); 1098 | } 1099 | opt++; 1100 | } 1101 | 1102 | elog(ERROR, "curl option '%s' is not available for run-time configuration", curlopt); 1103 | PG_RETURN_BOOL(false); 1104 | } 1105 | 1106 | 1107 | /** 1108 | * Master HTTP request function, takes in an http_request tuple and outputs 1109 | * an http_response tuple. 1110 | */ 1111 | Datum http_request(PG_FUNCTION_ARGS); 1112 | PG_FUNCTION_INFO_V1(http_request); 1113 | Datum http_request(PG_FUNCTION_ARGS) 1114 | { 1115 | /* Input */ 1116 | HeapTupleHeader rec; 1117 | HeapTupleData tuple; 1118 | Oid tup_type; 1119 | int32 tup_typmod; 1120 | TupleDesc tup_desc; 1121 | int ncolumns; 1122 | Datum *values; 1123 | bool *nulls; 1124 | 1125 | char *uri; 1126 | char *method_str; 1127 | http_method method; 1128 | 1129 | /* Processing */ 1130 | CURLcode err; 1131 | char http_error_buffer[CURL_ERROR_SIZE] = "\0"; 1132 | 1133 | struct curl_slist *headers = NULL; 1134 | StringInfoData si_data; 1135 | StringInfoData si_headers; 1136 | StringInfoData si_read; 1137 | 1138 | int http_return; 1139 | long long_status; 1140 | int status; 1141 | char *content_type = NULL; 1142 | int content_charset = -1; 1143 | 1144 | /* Output */ 1145 | HeapTuple tuple_out; 1146 | 1147 | /* Version check */ 1148 | http_check_curl_version(curl_version_info(CURLVERSION_NOW)); 1149 | 1150 | /* We cannot handle a null request */ 1151 | if ( ! PG_ARGISNULL(0) ) 1152 | rec = PG_GETARG_HEAPTUPLEHEADER(0); 1153 | else 1154 | { 1155 | elog(ERROR, "An http_request must be provided"); 1156 | PG_RETURN_NULL(); 1157 | } 1158 | 1159 | /************************************************************************* 1160 | * Build and run a curl request from the http_request argument 1161 | *************************************************************************/ 1162 | 1163 | /* Zero out static memory */ 1164 | memset(http_error_buffer, 0, sizeof(http_error_buffer)); 1165 | 1166 | /* Extract type info from the tuple itself */ 1167 | tup_type = HeapTupleHeaderGetTypeId(rec); 1168 | tup_typmod = HeapTupleHeaderGetTypMod(rec); 1169 | tup_desc = lookup_rowtype_tupdesc(tup_type, tup_typmod); 1170 | ncolumns = tup_desc->natts; 1171 | 1172 | /* Build a temporary HeapTuple control structure */ 1173 | tuple.t_len = HeapTupleHeaderGetDatumLength(rec); 1174 | ItemPointerSetInvalid(&(tuple.t_self)); 1175 | tuple.t_tableOid = InvalidOid; 1176 | tuple.t_data = rec; 1177 | 1178 | /* Prepare for values / nulls */ 1179 | values = (Datum *) palloc0(ncolumns * sizeof(Datum)); 1180 | nulls = (bool *) palloc0(ncolumns * sizeof(bool)); 1181 | 1182 | /* Break down the tuple into values/nulls lists */ 1183 | heap_deform_tuple(&tuple, tup_desc, values, nulls); 1184 | 1185 | /* Read the URI */ 1186 | if ( nulls[REQ_URI] ) 1187 | elog(ERROR, "http_request.uri is NULL"); 1188 | uri = TextDatumGetCString(values[REQ_URI]); 1189 | 1190 | /* Read the method */ 1191 | if ( nulls[REQ_METHOD] ) 1192 | elog(ERROR, "http_request.method is NULL"); 1193 | method_str = TextDatumGetCString(values[REQ_METHOD]); 1194 | method = request_type(method_str); 1195 | elog(DEBUG2, "pgsql-http: method_str: '%s', method: %d", method_str, method); 1196 | 1197 | /* Set up global HTTP handle */ 1198 | g_http_handle = http_get_handle(); 1199 | 1200 | /* Set up the error buffer */ 1201 | CURL_SETOPT(g_http_handle, CURLOPT_ERRORBUFFER, http_error_buffer); 1202 | 1203 | /* Set the target URL */ 1204 | CURL_SETOPT(g_http_handle, CURLOPT_URL, uri); 1205 | 1206 | 1207 | /* Restrict to just http/https. Leaving unrestricted */ 1208 | /* opens possibility of users requesting file:/// urls */ 1209 | /* locally */ 1210 | #if LIBCURL_VERSION_NUM >= 0x075400 /* 7.84.0 */ 1211 | CURL_SETOPT(g_http_handle, CURLOPT_PROTOCOLS_STR, "http,https"); 1212 | #else 1213 | CURL_SETOPT(g_http_handle, CURLOPT_PROTOCOLS, CURLPROTO_HTTP | CURLPROTO_HTTPS); 1214 | #endif 1215 | 1216 | if ( curlopt_is_set(CURLOPT_TCP_KEEPALIVE) ) 1217 | { 1218 | /* Keep sockets held open */ 1219 | CURL_SETOPT(g_http_handle, CURLOPT_FORBID_REUSE, 0); 1220 | } 1221 | else 1222 | { 1223 | /* Keep sockets from being held open */ 1224 | CURL_SETOPT(g_http_handle, CURLOPT_FORBID_REUSE, 1); 1225 | } 1226 | 1227 | /* Set up the write-back function */ 1228 | CURL_SETOPT(g_http_handle, CURLOPT_WRITEFUNCTION, http_writeback); 1229 | 1230 | /* Set up the write-back buffer */ 1231 | initStringInfo(&si_data); 1232 | initStringInfo(&si_headers); 1233 | CURL_SETOPT(g_http_handle, CURLOPT_WRITEDATA, (void*)(&si_data)); 1234 | CURL_SETOPT(g_http_handle, CURLOPT_WRITEHEADER, (void*)(&si_headers)); 1235 | 1236 | #if LIBCURL_VERSION_NUM >= 0x072700 /* 7.39.0 */ 1237 | /* Connect the progress callback for interrupt support */ 1238 | CURL_SETOPT(g_http_handle, CURLOPT_XFERINFOFUNCTION, http_progress_callback); 1239 | CURL_SETOPT(g_http_handle, CURLOPT_NOPROGRESS, 0); 1240 | #endif 1241 | 1242 | /* Set the HTTP content encoding to all curl supports */ 1243 | CURL_SETOPT(g_http_handle, CURLOPT_ACCEPT_ENCODING, ""); 1244 | 1245 | if ( method != HTTP_HEAD ) 1246 | { 1247 | /* Follow redirects, as many as 5 */ 1248 | CURL_SETOPT(g_http_handle, CURLOPT_FOLLOWLOCATION, 1); 1249 | CURL_SETOPT(g_http_handle, CURLOPT_MAXREDIRS, 5); 1250 | } 1251 | 1252 | if ( curlopt_is_set(CURLOPT_TCP_KEEPALIVE) ) 1253 | { 1254 | /* Add a keep alive option to the headers to reuse network sockets */ 1255 | headers = curl_slist_append(headers, "Connection: Keep-Alive"); 1256 | } 1257 | else 1258 | { 1259 | /* Add a close option to the headers to avoid open network sockets */ 1260 | headers = curl_slist_append(headers, "Connection: close"); 1261 | } 1262 | 1263 | /* Let our charset preference be known */ 1264 | headers = curl_slist_append(headers, "Charsets: utf-8"); 1265 | 1266 | /* Handle optional headers */ 1267 | if ( ! nulls[REQ_HEADERS] ) 1268 | { 1269 | ArrayType *array = DatumGetArrayTypeP(values[REQ_HEADERS]); 1270 | headers = header_array_to_slist(array, headers); 1271 | } 1272 | 1273 | /* If we have a payload we send it, assuming we're either POST, GET, PATCH, PUT or DELETE or UNKNOWN */ 1274 | if ( ! nulls[REQ_CONTENT] && values[REQ_CONTENT] ) 1275 | { 1276 | text *content_text; 1277 | long content_size; 1278 | char *cstr; 1279 | char buffer[1024]; 1280 | 1281 | /* Read the content type */ 1282 | if ( nulls[REQ_CONTENT_TYPE] || ! values[REQ_CONTENT_TYPE] ) 1283 | elog(ERROR, "http_request.content_type is NULL"); 1284 | cstr = TextDatumGetCString(values[REQ_CONTENT_TYPE]); 1285 | 1286 | /* Add content type to the headers */ 1287 | snprintf(buffer, sizeof(buffer), "Content-Type: %s", cstr); 1288 | headers = curl_slist_append(headers, buffer); 1289 | pfree(cstr); 1290 | 1291 | /* Read the content */ 1292 | content_text = DatumGetTextP(values[REQ_CONTENT]); 1293 | content_size = VARSIZE_ANY_EXHDR(content_text); 1294 | 1295 | if ( method == HTTP_GET || method == HTTP_POST || method == HTTP_DELETE ) 1296 | { 1297 | /* Add the content to the payload */ 1298 | CURL_SETOPT(g_http_handle, CURLOPT_POST, 1); 1299 | if ( method == HTTP_GET ) 1300 | { 1301 | /* Force the verb to be GET */ 1302 | CURL_SETOPT(g_http_handle, CURLOPT_CUSTOMREQUEST, "GET"); 1303 | } 1304 | else if( method == HTTP_DELETE ) 1305 | { 1306 | /* Force the verb to be DELETE */ 1307 | CURL_SETOPT(g_http_handle, CURLOPT_CUSTOMREQUEST, "DELETE"); 1308 | } 1309 | 1310 | CURL_SETOPT(g_http_handle, CURLOPT_POSTFIELDS, (char *)(VARDATA(content_text))); 1311 | CURL_SETOPT(g_http_handle, CURLOPT_POSTFIELDSIZE, content_size); 1312 | } 1313 | else if ( method == HTTP_PUT || method == HTTP_PATCH || method == HTTP_UNKNOWN ) 1314 | { 1315 | if ( method == HTTP_PATCH ) 1316 | CURL_SETOPT(g_http_handle, CURLOPT_CUSTOMREQUEST, "PATCH"); 1317 | 1318 | /* Assume the user knows what they are doing and pass unchanged */ 1319 | if ( method == HTTP_UNKNOWN ) 1320 | CURL_SETOPT(g_http_handle, CURLOPT_CUSTOMREQUEST, method_str); 1321 | 1322 | initStringInfo(&si_read); 1323 | appendBinaryStringInfo(&si_read, VARDATA(content_text), content_size); 1324 | CURL_SETOPT(g_http_handle, CURLOPT_UPLOAD, 1); 1325 | CURL_SETOPT(g_http_handle, CURLOPT_READFUNCTION, http_readback); 1326 | CURL_SETOPT(g_http_handle, CURLOPT_READDATA, &si_read); 1327 | CURL_SETOPT(g_http_handle, CURLOPT_INFILESIZE, content_size); 1328 | } 1329 | else 1330 | { 1331 | /* Never get here */ 1332 | elog(ERROR, "illegal HTTP method"); 1333 | } 1334 | } 1335 | else if ( method == HTTP_DELETE ) 1336 | { 1337 | CURL_SETOPT(g_http_handle, CURLOPT_CUSTOMREQUEST, "DELETE"); 1338 | } 1339 | else if ( method == HTTP_HEAD ) 1340 | { 1341 | CURL_SETOPT(g_http_handle, CURLOPT_NOBODY, 1); 1342 | } 1343 | else if ( method == HTTP_PUT || method == HTTP_POST ) 1344 | { 1345 | /* If we had a content we do not reach that part */ 1346 | elog(ERROR, "http_request.content is NULL"); 1347 | } 1348 | else if ( method == HTTP_UNKNOWN ){ 1349 | /* Assume the user knows what they are doing and pass unchanged */ 1350 | CURL_SETOPT(g_http_handle, CURLOPT_CUSTOMREQUEST, method_str); 1351 | } 1352 | 1353 | pfree(method_str); 1354 | /* Set the headers */ 1355 | CURL_SETOPT(g_http_handle, CURLOPT_HTTPHEADER, headers); 1356 | 1357 | /************************************************************************* 1358 | * PERFORM THE REQUEST! 1359 | **************************************************************************/ 1360 | http_return = curl_easy_perform(g_http_handle); 1361 | elog(DEBUG2, "pgsql-http: queried '%s'", uri); 1362 | elog(DEBUG2, "pgsql-http: http_return '%d'", http_return); 1363 | 1364 | /* Clean up some input things we don't need anymore */ 1365 | ReleaseTupleDesc(tup_desc); 1366 | pfree(values); 1367 | pfree(nulls); 1368 | 1369 | /************************************************************************* 1370 | * Create an http_response object from the curl results 1371 | *************************************************************************/ 1372 | 1373 | /* Write out an error on failure */ 1374 | if ( http_return != CURLE_OK ) 1375 | { 1376 | curl_slist_free_all(headers); 1377 | curl_easy_cleanup(g_http_handle); 1378 | g_http_handle = NULL; 1379 | 1380 | #if LIBCURL_VERSION_NUM >= 0x072700 /* 7.39.0 */ 1381 | /* 1382 | * If the request was aborted by an interrupt request 1383 | * report back. 1384 | */ 1385 | if (http_return == CURLE_ABORTED_BY_CALLBACK) 1386 | elog(ERROR, "canceling statement due to user request"); 1387 | #endif 1388 | 1389 | http_error(http_return, http_error_buffer); 1390 | } 1391 | 1392 | /* Read the metadata from the handle directly */ 1393 | if ( (CURLE_OK != curl_easy_getinfo(g_http_handle, CURLINFO_RESPONSE_CODE, &long_status)) || 1394 | (CURLE_OK != curl_easy_getinfo(g_http_handle, CURLINFO_CONTENT_TYPE, &content_type)) ) 1395 | { 1396 | curl_slist_free_all(headers); 1397 | curl_easy_cleanup(g_http_handle); 1398 | g_http_handle = NULL; 1399 | ereport(ERROR, (errmsg("CURL: Error in curl_easy_getinfo"))); 1400 | } 1401 | 1402 | /* Prepare our return object */ 1403 | if (get_call_result_type(fcinfo, 0, &tup_desc) != TYPEFUNC_COMPOSITE) { 1404 | ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), 1405 | errmsg("%s called with incompatible return type", __func__))); 1406 | } 1407 | 1408 | ncolumns = tup_desc->natts; 1409 | values = palloc0(sizeof(Datum)*ncolumns); 1410 | nulls = palloc0(sizeof(bool)*ncolumns); 1411 | 1412 | /* Status code */ 1413 | status = long_status; 1414 | values[RESP_STATUS] = Int32GetDatum(status); 1415 | nulls[RESP_STATUS] = false; 1416 | 1417 | /* Content type */ 1418 | if ( content_type ) 1419 | { 1420 | List *ctl; 1421 | ListCell *lc; 1422 | 1423 | values[RESP_CONTENT_TYPE] = CStringGetTextDatum(content_type); 1424 | nulls[RESP_CONTENT_TYPE] = false; 1425 | 1426 | /* Read the character set name out of the content type */ 1427 | /* if there is one in there */ 1428 | /* text/html; charset=iso-8859-1 */ 1429 | if ( SplitIdentifierString(pstrdup(content_type), ';', &ctl) ) 1430 | { 1431 | foreach(lc, ctl) 1432 | { 1433 | /* charset=iso-8859-1 */ 1434 | const char *param = (const char *) lfirst(lc); 1435 | const char *paramtype = "charset="; 1436 | if ( http_strcasestr(param, paramtype) ) 1437 | { 1438 | /* iso-8859-1 */ 1439 | const char *charset = param + strlen(paramtype); 1440 | content_charset = pg_char_to_encoding(charset); 1441 | break; 1442 | } 1443 | } 1444 | } 1445 | } 1446 | else 1447 | { 1448 | values[RESP_CONTENT_TYPE] = (Datum)0; 1449 | nulls[RESP_CONTENT_TYPE] = true; 1450 | } 1451 | 1452 | /* Headers array */ 1453 | if ( si_headers.len ) 1454 | { 1455 | /* Strip the carriage-returns, because who cares? */ 1456 | string_info_remove_cr(&si_headers); 1457 | values[RESP_HEADERS] = PointerGetDatum(header_string_to_array(&si_headers)); 1458 | nulls[RESP_HEADERS] = false; 1459 | } 1460 | else 1461 | { 1462 | values[RESP_HEADERS] = (Datum)0; 1463 | nulls[RESP_HEADERS] = true; 1464 | } 1465 | 1466 | /* Content */ 1467 | if ( si_data.len ) 1468 | { 1469 | char *content_str; 1470 | size_t content_len; 1471 | elog(DEBUG2, "pgsql-http: content_charset = %d", content_charset); 1472 | 1473 | /* Apply character transcoding if necessary */ 1474 | if ( content_charset < 0 ) 1475 | { 1476 | content_str = si_data.data; 1477 | content_len = si_data.len; 1478 | } 1479 | else 1480 | { 1481 | content_str = pg_any_to_server(si_data.data, si_data.len, content_charset); 1482 | content_len = strlen(content_str); 1483 | } 1484 | 1485 | values[RESP_CONTENT] = PointerGetDatum(cstring_to_text_with_len(content_str, content_len)); 1486 | nulls[RESP_CONTENT] = false; 1487 | } 1488 | else 1489 | { 1490 | values[RESP_CONTENT] = (Datum)0; 1491 | nulls[RESP_CONTENT] = true; 1492 | } 1493 | 1494 | /* Build up a tuple from values/nulls lists */ 1495 | tuple_out = heap_form_tuple(tup_desc, values, nulls); 1496 | 1497 | /* Clean up */ 1498 | ReleaseTupleDesc(tup_desc); 1499 | if ( ! curlopt_is_set(CURLOPT_TCP_KEEPALIVE) ) 1500 | { 1501 | curl_easy_cleanup(g_http_handle); 1502 | g_http_handle = NULL; 1503 | } 1504 | curl_slist_free_all(headers); 1505 | pfree(si_headers.data); 1506 | pfree(si_data.data); 1507 | pfree(values); 1508 | pfree(nulls); 1509 | 1510 | /* Return */ 1511 | PG_RETURN_DATUM(HeapTupleGetDatum(tuple_out)); 1512 | } 1513 | 1514 | 1515 | 1516 | 1517 | /* URL Encode Escape Chars */ 1518 | /* 45-46 (-.) 48-57 (0-9) 65-90 (A-Z) */ 1519 | /* 95 (_) 97-122 (a-z) 126 (~) */ 1520 | 1521 | static int chars_to_not_encode[] = { 1522 | 0,0,0,0,0,0,0,0,0,0, 1523 | 0,0,0,0,0,0,0,0,0,0, 1524 | 0,0,0,0,0,0,0,0,0,0, 1525 | 0,0,0,0,0,0,0,0,0,0, 1526 | 0,0,0,0,0,1,1,0,1,1, 1527 | 1,1,1,1,1,1,1,1,0,0, 1528 | 0,0,0,0,0,1,1,1,1,1, 1529 | 1,1,1,1,1,1,1,1,1,1, 1530 | 1,1,1,1,1,1,1,1,1,1, 1531 | 1,0,0,0,0,1,0,1,1,1, 1532 | 1,1,1,1,1,1,1,1,1,1, 1533 | 1,1,1,1,1,1,1,1,1,1, 1534 | 1,1,1,0,0,0,1,0 1535 | }; 1536 | 1537 | 1538 | 1539 | /* 1540 | * Take in a text pointer and output a cstring with 1541 | * all encodable characters encoded. 1542 | */ 1543 | static char* 1544 | urlencode_cstr(const char* str_in, size_t str_in_len) 1545 | { 1546 | char *str_out, *ptr; 1547 | size_t i; 1548 | int rv; 1549 | 1550 | if (!str_in_len) return pstrdup(""); 1551 | 1552 | /* Prepare the output string, encoding can fluff the ouput */ 1553 | /* considerably */ 1554 | str_out = palloc0(str_in_len * 4); 1555 | ptr = str_out; 1556 | 1557 | for (i = 0; i < str_in_len; i++) 1558 | { 1559 | unsigned char c = str_in[i]; 1560 | 1561 | /* Break on NULL */ 1562 | if (c == '\0') 1563 | break; 1564 | 1565 | /* Replace ' ' with '+' */ 1566 | if (c == ' ') 1567 | { 1568 | *ptr = '+'; 1569 | ptr++; 1570 | continue; 1571 | } 1572 | 1573 | /* Pass basic characters through */ 1574 | if ((c < 127) && chars_to_not_encode[(int)(str_in[i])]) 1575 | { 1576 | *ptr = str_in[i]; 1577 | ptr++; 1578 | continue; 1579 | } 1580 | 1581 | /* Encode the remaining chars */ 1582 | rv = snprintf(ptr, 4, "%%%02X", c); 1583 | if ( rv < 0 ) 1584 | return NULL; 1585 | 1586 | /* Move pointer forward */ 1587 | ptr += 3; 1588 | } 1589 | *ptr = '\0'; 1590 | 1591 | return str_out; 1592 | } 1593 | 1594 | /** 1595 | * Utility function for users building URL encoded requests, applies 1596 | * standard URL encoding to an input string. 1597 | */ 1598 | Datum urlencode(PG_FUNCTION_ARGS); 1599 | PG_FUNCTION_INFO_V1(urlencode); 1600 | Datum urlencode(PG_FUNCTION_ARGS) 1601 | { 1602 | /* Declare SQL function strict, so no test for NULL input */ 1603 | text *txt = PG_GETARG_TEXT_P(0); 1604 | char *encoded = urlencode_cstr(VARDATA(txt), VARSIZE_ANY_EXHDR(txt)); 1605 | if (encoded) 1606 | PG_RETURN_TEXT_P(cstring_to_text(encoded)); 1607 | else 1608 | PG_RETURN_NULL(); 1609 | } 1610 | 1611 | /** 1612 | * Treat the top level jsonb map as a key/value set 1613 | * to be fed into urlencode and return a correctly 1614 | * encoded data string. 1615 | */ 1616 | Datum urlencode_jsonb(PG_FUNCTION_ARGS); 1617 | PG_FUNCTION_INFO_V1(urlencode_jsonb); 1618 | Datum urlencode_jsonb(PG_FUNCTION_ARGS) 1619 | { 1620 | bool skipNested = false; 1621 | Jsonb* jb = PG_GETARG_JSONB_P(0); 1622 | JsonbIterator *it; 1623 | JsonbValue v; 1624 | JsonbIteratorToken r; 1625 | StringInfoData si; 1626 | size_t count = 0; 1627 | 1628 | if (!JB_ROOT_IS_OBJECT(jb)) 1629 | { 1630 | ereport(ERROR, 1631 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 1632 | errmsg("cannot call %s on a non-object", __func__))); 1633 | } 1634 | 1635 | /* Buffer to write complete output into */ 1636 | initStringInfo(&si); 1637 | 1638 | it = JsonbIteratorInit(&jb->root); 1639 | while ((r = JsonbIteratorNext(&it, &v, skipNested)) != WJB_DONE) 1640 | { 1641 | skipNested = true; 1642 | 1643 | if (r == WJB_KEY) 1644 | { 1645 | char *key, *key_enc, *value, *value_enc; 1646 | 1647 | /* Skip zero-length key */ 1648 | if(!v.val.string.len) continue; 1649 | 1650 | /* Read and encode the key */ 1651 | key = pnstrdup(v.val.string.val, v.val.string.len); 1652 | key_enc = urlencode_cstr(v.val.string.val, v.val.string.len); 1653 | 1654 | /* Read the value for this key */ 1655 | #if PG_VERSION_NUM < 130000 1656 | { 1657 | JsonbValue k; 1658 | k.type = jbvString; 1659 | k.val.string.val = key; 1660 | k.val.string.len = strlen(key); 1661 | v = *findJsonbValueFromContainer(&jb->root, JB_FOBJECT, &k); 1662 | } 1663 | #else 1664 | getKeyJsonValueFromContainer(&jb->root, key, strlen(key), &v); 1665 | #endif 1666 | /* Read and encode the value */ 1667 | switch(v.type) 1668 | { 1669 | case jbvString: { 1670 | value = pnstrdup(v.val.string.val, v.val.string.len); 1671 | break; 1672 | } 1673 | case jbvNumeric: { 1674 | value = numeric_normalize(v.val.numeric); 1675 | break; 1676 | } 1677 | case jbvBool: { 1678 | value = pstrdup(v.val.boolean ? "true" : "false"); 1679 | break; 1680 | } 1681 | case jbvNull: { 1682 | value = pstrdup(""); 1683 | break; 1684 | } 1685 | default: { 1686 | elog(DEBUG2, "skipping non-scalar value of '%s'", key); 1687 | continue; 1688 | } 1689 | 1690 | } 1691 | /* Write the result */ 1692 | value_enc = urlencode_cstr(value, strlen(value)); 1693 | if (count++) appendStringInfo(&si, "&"); 1694 | appendStringInfo(&si, "%s=%s", key_enc, value_enc); 1695 | 1696 | /* Clean up temporary strings */ 1697 | if (key) pfree(key); 1698 | if (value) pfree(value); 1699 | if (key_enc) pfree(key_enc); 1700 | if (value_enc) pfree(value_enc); 1701 | } 1702 | } 1703 | 1704 | if (si.len) 1705 | PG_RETURN_TEXT_P(cstring_to_text_with_len(si.data, si.len)); 1706 | else 1707 | PG_RETURN_NULL(); 1708 | } 1709 | 1710 | Datum bytea_to_text(PG_FUNCTION_ARGS); 1711 | PG_FUNCTION_INFO_V1(bytea_to_text); 1712 | Datum bytea_to_text(PG_FUNCTION_ARGS) 1713 | { 1714 | bytea *b = PG_GETARG_BYTEA_P(0); 1715 | text *t = palloc(VARSIZE_ANY(b)); 1716 | memcpy(t, b, VARSIZE(b)); 1717 | PG_RETURN_TEXT_P(t); 1718 | } 1719 | 1720 | Datum text_to_bytea(PG_FUNCTION_ARGS); 1721 | PG_FUNCTION_INFO_V1(text_to_bytea); 1722 | Datum text_to_bytea(PG_FUNCTION_ARGS) 1723 | { 1724 | text *t = PG_GETARG_TEXT_P(0); 1725 | bytea *b = palloc(VARSIZE_ANY(t)); 1726 | memcpy(b, t, VARSIZE(t)); 1727 | PG_RETURN_TEXT_P(b); 1728 | } 1729 | 1730 | 1731 | // Local Variables: 1732 | // mode: C++ 1733 | // tab-width: 4 1734 | // c-basic-offset: 4 1735 | // indent-tabs-mode: t 1736 | // End: 1737 | -------------------------------------------------------------------------------- /http.control: -------------------------------------------------------------------------------- 1 | default_version = '1.7' 2 | module_pathname = '$libdir/http' 3 | comment = 'HTTP client for PostgreSQL, allows web page retrieval inside the database.' 4 | -------------------------------------------------------------------------------- /sql/http.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION http; 2 | SET http.server_host = 'http://localhost:9080'; 3 | set http.timeout_msec = 10000; 4 | SELECT http_set_curlopt('CURLOPT_TIMEOUT', '10'); 5 | -- if local server not up use global one 6 | DO language plpgsql $$ 7 | BEGIN 8 | BEGIN 9 | PERFORM http_get(current_setting('http.server_host') || '/status/202'); 10 | EXCEPTION WHEN OTHERS THEN 11 | SET http.server_host = 'http://httpbin.org'; 12 | END; 13 | END; 14 | $$; 15 | 16 | -- Status code 17 | SELECT status 18 | FROM http_get(current_setting('http.server_host') || '/status/202'); 19 | 20 | -- Headers 21 | SELECT lower(field) AS field, value 22 | FROM ( 23 | SELECT (unnest(headers)).* 24 | FROM http_get(current_setting('http.server_host') || '/response-headers?Abcde=abcde') 25 | ) a 26 | WHERE field ILIKE 'Abcde'; 27 | 28 | -- GET 29 | SELECT status, 30 | content::json->'args'->>'foo' AS args, 31 | content::json->>'method' AS method 32 | FROM http_get(current_setting('http.server_host') || '/anything?foo=bar'); 33 | 34 | -- GET with data 35 | SELECT status, 36 | content::json->'args'->>'this' AS args, 37 | replace(content::json->>'url',current_setting('http.server_host'),'') AS path, 38 | content::json->>'method' AS method 39 | FROM http_get(current_setting('http.server_host') || '/anything', jsonb_build_object('this', 'that')); 40 | 41 | -- GET with data 42 | SELECT status, 43 | content::json->>'args' as args, 44 | (content::json)->>'data' as data, 45 | content::json->>'method' as method 46 | FROM http(('GET', current_setting('http.server_host') || '/anything', NULL, 'application/json', '{"search": "toto"}')); 47 | 48 | -- DELETE 49 | SELECT status, 50 | content::json->'args'->>'foo' AS args, 51 | replace(content::json->>'url',current_setting('http.server_host'),'') AS path, 52 | content::json->>'method' AS method 53 | FROM http_delete(current_setting('http.server_host') || '/anything?foo=bar'); 54 | 55 | -- DELETE with payload 56 | SELECT status, 57 | content::json->'args'->>'foo' AS args, 58 | replace(content::json->>'url',current_setting('http.server_host'),'') AS path, 59 | content::json->>'method' AS method, 60 | content::json->>'data' AS data 61 | FROM http_delete(current_setting('http.server_host') || '/anything?foo=bar', 'payload', 'text/plain'); 62 | 63 | -- PUT 64 | SELECT status, 65 | content::json->>'data' AS data, 66 | content::json->'args'->>'foo' AS args, 67 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 68 | content::json->>'method' AS method 69 | FROM http_put(current_setting('http.server_host') || '/anything?foo=bar','payload','text/plain'); 70 | 71 | -- PATCH 72 | SELECT status, 73 | content::json->>'data' AS data, 74 | content::json->'args'->>'foo' AS args, 75 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 76 | content::json->>'method' AS method 77 | FROM http_patch(current_setting('http.server_host') || '/anything?foo=bar','{"this":"that"}','application/json'); 78 | 79 | -- POST 80 | SELECT status, 81 | content::json->>'data' AS data, 82 | content::json->'args'->>'foo' AS args, 83 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 84 | content::json->>'method' AS method 85 | FROM http_post(current_setting('http.server_host') || '/anything?foo=bar','payload','text/plain'); 86 | 87 | -- POST with json data 88 | SELECT status, 89 | content::json->'form'->>'this' AS args, 90 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 91 | content::json->>'method' AS method 92 | FROM http_post(current_setting('http.server_host') || '/anything', jsonb_build_object('this', 'that')); 93 | 94 | -- POST with data 95 | SELECT status, 96 | content::json->'form'->>'key1' AS key1, 97 | content::json->'form'->>'key2' AS key2, 98 | replace(content::json->>'url', current_setting('http.server_host'),'') AS path, 99 | content::json->>'method' AS method 100 | FROM http_post(current_setting('http.server_host') || '/anything', 'key1=value1&key2=value2','application/x-www-form-urlencoded'); 101 | 102 | -- HEAD 103 | SELECT lower(field) AS field, value 104 | FROM ( 105 | SELECT (unnest(headers)).* 106 | FROM http_head(current_setting('http.server_host') || '/response-headers?Abcde=abcde') 107 | ) a 108 | WHERE field ILIKE 'Abcde'; 109 | 110 | -- Follow redirect 111 | SELECT status, 112 | replace((content::json)->>'url', current_setting('http.server_host'),'') AS path 113 | FROM http_get(current_setting('http.server_host') || '/redirect-to?url=get'); 114 | 115 | -- Request image 116 | WITH 117 | http AS ( 118 | SELECT * FROM http_get(current_setting('http.server_host') || '/image/png') 119 | ), 120 | headers AS ( 121 | SELECT (unnest(headers)).* FROM http 122 | ) 123 | SELECT 124 | http.content_type, 125 | length(text_to_bytea(http.content)) AS length_binary 126 | FROM http, headers 127 | WHERE field ilike 'Content-Type'; 128 | 129 | -- Alter options and and reset them and throw errors 130 | SELECT http_set_curlopt('CURLOPT_PROXY', '127.0.0.1'); 131 | -- Error because proxy is not there 132 | DO $$ 133 | BEGIN 134 | SELECT status FROM http_get(current_setting('http.server_host') || '/status/555'); 135 | EXCEPTION 136 | WHEN OTHERS THEN 137 | RAISE WARNING 'Failed to connect'; 138 | END; 139 | $$; 140 | -- Still an error 141 | DO $$ 142 | BEGIN 143 | SELECT status FROM http_get(current_setting('http.server_host') || '/status/555'); 144 | EXCEPTION 145 | WHEN OTHERS THEN 146 | RAISE WARNING 'Failed to connect'; 147 | END; 148 | $$; 149 | -- Reset options 150 | SELECT http_reset_curlopt(); 151 | -- Now it should work 152 | SELECT status FROM http_get(current_setting('http.server_host') || '/status/555'); 153 | 154 | -- Alter the default timeout and then run a query that is longer than 155 | -- the default (5s), but shorter than the new timeout 156 | SELECT http_set_curlopt('CURLOPT_TIMEOUT_MS', '10000'); 157 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 158 | 159 | -- Test new GUC feature 160 | SET http.CURLOPT_TIMEOUT_MS = '10'; 161 | -- should fail 162 | -- Still an error 163 | DO $$ 164 | BEGIN 165 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 166 | EXCEPTION 167 | WHEN OTHERS THEN 168 | RAISE WARNING 'Failed to connect'; 169 | END; 170 | $$; 171 | 172 | SET http.CURLOPT_TIMEOUT_MS = '10000'; 173 | --should pass 174 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 175 | 176 | -- SET to bogus file 177 | SET http.CURLOPT_CAINFO = '/path/to/somebundle.crt'; 178 | 179 | -- should fail 180 | DO $$ 181 | BEGIN 182 | SELECT status FROM http_get('https://postgis.net'); 183 | EXCEPTION 184 | WHEN OTHERS THEN 185 | RAISE WARNING 'Invalid cert file'; 186 | END; 187 | $$; 188 | 189 | -- set to ignore cert 190 | SET http.CURLOPT_SSL_VERIFYPEER = '0'; 191 | 192 | -- should pass 193 | SELECT status FROM http_get('https://postgis.net'); 194 | 195 | SHOW http.CURLOPT_CAINFO; 196 | 197 | -- reset it 198 | RESET http.CURLOPT_CAINFO; 199 | 200 | SELECT status FROM http_get(current_setting('http.server_host') || '/delay/7'); 201 | 202 | -- Check that statement interruption works 203 | SET statement_timeout = 200; 204 | CREATE TEMPORARY TABLE timer AS 205 | SELECT now() AS start; 206 | SELECT * 207 | FROM http_get(current_setting('http.server_host') || '/delay/7'); 208 | SELECT round(extract(epoch FROM now() - start) * 10) AS m 209 | FROM timer; 210 | DROP TABLE timer; 211 | --------------------------------------------------------------------------------