Skip to content

AWS S3

AWS S3 is an object storage service offering industry-leading scalability, data availability, security, and performance. It is read-only and supports below file formats:

The S3 Wrapper allows you to read data of below formats from S3 within your Postgres database.

  1. CSV - with or without header line
  2. JSON Lines
  3. Parquet

The S3 Wrapper also supports below compression algorithms:

  1. gzip
  2. bzip2
  3. xz
  4. zlib

Note for CSV and JSONL files: currently all columns in S3 files must be defined in the foreign table and their types must be text type.

Note for Parquet files: the whole Parquet file will be loaded into local memory if it is compressed, so keep the file size as small as possible.

Warning

Restoring a logical backup of a database with a materialized view using a foreign table can fail. For this reason, either do not use foreign tables in materialized views or use them in databases with physical backups enabled.

Supported Data Types For Parquet File

The S3 Wrapper uses Parquet file data types from arrow_array::types, below are their mappings to Postgres data types.

Postgres Type Parquet Type
boolean BooleanType
char Int8Type
smallint Int16Type
real Float32Type
integer Int32Type
double precision Float64Type
bigint Int64Type
numeric Float64Type
text ByteArrayType
date Date64Type
timestamp TimestampNanosecondType
timestamptz TimestampNanosecondType

Preparation

Before you get started, make sure the wrappers extension is installed on your database:

1
create extension if not exists wrappers with schema extensions;

and then create the foreign data wrapper:

1
2
3
create foreign data wrapper s3_wrapper
  handler s3_fdw_handler
  validator s3_fdw_validator;

Secure your credentials (optional)

By default, Postgres stores FDW credentials inide pg_catalog.pg_foreign_server in plain text. Anyone with access to this table will be able to view these credentials. Wrappers is designed to work with Vault, which provides an additional level of security for storing credentials. We recommend using Vault to store your credentials.

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
-- Save your AWS credential in Vault and retrieve the `key_id`
insert into vault.secrets (name, secret)
values (
  'vault_access_key_id',
  '<access key id>'
)
returning key_id;

insert into vault.secrets (name, secret)
values (
  'vault_secret_access_key',
  '<secret access key>'
)
returning key_id;

Connecting to S3

We need to provide Postgres with the credentials to connect to S3, and any additional options. We can do this using the create server command:

1
2
3
4
5
6
7
create server s3_server
  foreign data wrapper s3_wrapper
  options (
    vault_access_key_id '<your vault_access_key_id from above>',
    vault_secret_access_key '<your vault_secret_access_key from above>',
    aws_region 'us-east-1'
  );
1
2
3
4
5
6
7
create server s3_server
  foreign data wrapper s3_wrapper
  options (
    aws_access_key_id 'your_aws_access_key_id',
    aws_secret_access_key 'your_aws_secret_access_key',
    aws_region 'us-east-1'
  );

The full list of options are below:

  • aws_access_key_id (required) - Your access key
  • aws_secret_access_key (required) - Your secret key
  • aws_region (required) - The region of your bucket (if providing an endpoint URL with a region in it, make sure that they are the same)
  • endpoint_url (optional) - An optional URL to allow connection to S3-compliant providers (i.e. Wasabi, Cloudflare R2, Backblaze B2, DigitalOcean Spaces)

Connecting to S3-compliant Providers - Wasabi

1
2
3
4
5
6
7
8
create server s3_server
      foreign data wrapper s3_wrapper
      options (
        aws_access_key_id 'you_wasabi_access_key',
        aws_secret_access_key 'your_wasabi_secret_access_key',
        aws_region 'eu-central-1',
        endpoint_url 'https://s3.eu-central-1.wasabisys.com'
      );

Creating Foreign Tables

The S3 Wrapper supports data reads from S3.

Integration Select Insert Update Delete Truncate
S3

For example:

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
create foreign table s3_table_csv (
  name text,
  sex text,
  age text,
  height text,
  weight text
)
  server s3_server
  options (
    uri 's3://bucket/s3_table.csv',
    format 'csv',
    has_header 'true'
  );

One file in S3 corresponds a foreign table in Postgres. For CSV and JSONL file, all columns must be present in the foreign table and type must be text. You can do custom transformations, like type conversion, by creating a view on top of the foreign table or using a subquery.

For Parquet file, no need to define all columns in the foreign table but column names must match between Parquet file and its foreign table.

Foreign table options

The full list of foreign table options are below:

  • uri - S3 URI, required. For example, s3://bucket/s3_table.csv
  • format - File format, required. csv, jsonl, or parquet
  • has_header - If the CSV file has header, optional. true or false, default is false
  • compress - Compression algorithm, optional. One of gzip, bzip2, xz, zlib, default is no compression

Query Pushdown Support

This FDW doesn't support query pushdown.

Examples

Some examples on how to use S3 foreign tables.

Basic example

This will create some "foreign table" inside your Postgres database can read data from S3:

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
-- CSV file, no compression
create foreign table s3_table_csv (
  name text,
  sex text,
  age text,
  height text,
  weight text
)
  server s3_server
  options (
    uri 's3://bucket/s3_table.csv',
    format 'csv',
    has_header 'true'
  );

-- JSON line file, no compression
create foreign table s3_table_jsonl (
  name text,
  sex text,
  age text,
  height text,
  weight text
)
  server s3_server
  options (
    uri 's3://bucket/s3_table.jsonl',
    format 'jsonl'
  );

-- GZIP compressed CSV file
create foreign table s3_table_csv_gzip (
  name text,
  sex text,
  age text,
  height text,
  weight text
)
  server s3_server
  options (
    uri 's3://bucket/s3_table.csv.gz',
    format 'csv',
    has_header 'true',
    compress 'gzip'
  );

-- Parquet file, no compression
create foreign table s3_table_parquet (
  id integer,
  bool_col boolean,
  bigint_col bigint,
  float_col real,
  date_string_col text,
  timestamp_col timestamp
)
  server s3_server
  options (
    uri 's3://bucket/s3_table.parquet',
    format 'parquet'
  );

-- GZIP compressed Parquet file
create foreign table s3_table_parquet_gz (
  id integer,
  bool_col boolean,
  bigint_col bigint,
  float_col real,
  date_string_col text,
  timestamp_col timestamp
)
  server s3_server
  options (
    uri 's3://bucket/s3_table.parquet.gz',
    format 'parquet',
    compress 'gzip'
  );