Command Reference

Data Wrapper

CREATE SERVER

Create new server objects.

Syntax

CREATE SERVER [IF NOT EXISTS] <server_name>
    FOREIGN DATA WRAPPER <foreign_data_wrapper_name>
     WITH ( <option> = <value> [, ... ] )

Description

A foreign server object represents a named external datasource, along with configuration information required to access the datasource. Server objects are referenced during foreign table creation in order to indicate the backing datasource for the created table.

Parameters

Foreign Server Options for File Data Wrappers (delimited_file, parquet_file, and regex_parsed_file)

Foreign Server Options for ODBC Data Wrapper

ODBC HeavyConnect is currently in beta.

Examples

Create a local server that uses the delimited_file data wrapper and the file path /home/my_user/data/csv/:

CREATE SERVER my_csv_server FOREIGN DATA WRAPPER delimited_file WITH (
  storage_type = 'LOCAL_FILE', 
  base_path = '/home/my_user/data/csv/'
);

Create an AWS Server that uses the delimited_file data wrapper with an AWS S3 bucket "fsi-s3-bucket" in the us-west-1 AWS region:

CREATE SERVER my_aws_server FOREIGN DATA WRAPPER delimited_file WITH (
  storage_type = 'AWS_S3', 
  s3_bucket = 'fsi-s3-bucket', 
  aws_region = 'us-west-1'
);

Create an ODBC server using a data source name (DSN):

CREATE SERVER my_postgres_server FOREIGN DATA WRAPPER odbc WITH (
  data_source_name = 'postgres_db_1'
);

Create an ODBC server using a connection string:

CREATE SERVER my_postgres_server FOREIGN DATA WRAPPER odbc WITH (
  connection_string = 'Driver=PostgreSQL;Database=my_postgres_db;Servername=my_postgres.example.com;Port=1234'
);

To prevent collisions with available HeavyDB default servers, server names with default*, system*, and internal* (case insensitive) prefixes are not allowed.

ALTER SERVER

Update server objects.

Syntax

ALTER SERVER <server_name>
    [ SET (<option> = <value> [, ... ] ) ]
ALTER SERVER <server_name> OWNER TO <new_owner>
ALTER SERVER <server_name> RENAME TO <new_server_name>
ALTER SERVER <server_name> SET FOREIGN DATA WRAPPER <foreign_data_wrapper_name>

Description

Allow users to update properties of existing server objects.

Parameters

Example: Update server property

Update the my_csv_server object's base path “/home/my_user/data/csv/” to “/home/my_user/data/new_csv/”:

ALTER SERVER my_csv_server WITH (base_path = '/home/my_user/data/new-csv/');

Example: Change server name

Change the my_csv_server object's name to my_new_csv_server:

ALTER SERVER my_csv_server RENAME TO my_new_csv_server;

DROP SERVER

Delete an existing server object

Syntax

DROP SERVER [ IF EXISTS ] <server_name>

Parameters

Example

Delete the my_csv_server server object:

DROP SERVER my_csv_server;

SHOW SERVERS

View information about existing server objects.

Syntax

SHOW SERVERS 
    [WHERE <metadata_name> { = | LIKE } <metadata_value>]

Column Results

Example - View all server objects in the current database

SHOW SERVERS;
Result:
server_name       | owner | data_wrapper   | options                                                                                | created_at
------------------+-------+----------------+----------------------------------------------------------------------------------------+----------------------
my_csv_server     | joe   | delimited_file | {"storage_type": "LOCAL_FILE", "base_path": "/home/my_user/data/csv/"}                 | 2019-11-15T23:54:35Z
my_parquet_server | admin | parquet_file   | {"storage_type": "AWS_S3", "s3_bucket": "my_parquet_files", "aws_region": "us-east-1"} | 2019-11-15T23:54:35Z

Example - View all server objects with the delimited_file data wrapper type

SHOW SERVERS WHERE data_wrapper = 'delimited_file';
Result:
server_name       | owner | data_wrapper   | options                                                                                | created_at
------------------+-------+----------------+----------------------------------------------------------------------------------------+----------------------
my_csv_server     | joe   | delimited_file | {"storage_type": "LOCAL_FILE", "base_path": "/home/my_user/data/csv/"}                 | 2019-11-15T23:54:35Z

Example - View all server objects with the name containing “csv”

SHOW SERVERS WHERE server_name LIKE '%csv%';
Result:
server_name       | owner | data_wrapper   | options                                                                                | created_at
------------------+-------+----------------+----------------------------------------------------------------------------------------+----------------------
my_csv_server     | joe   | delimited_file | {"storage_type": "LOCAL_FILE", "base_path": "/home/my_user/data/csv/"}                 | 2019-11-15T23:54:35Z

CREATE FOREIGN TABLE

Creates the foreign table.

Syntax

CREATE FOREIGN TABLE [ IF NOT EXISTS ] <table_name> (
  { <column_name> <data_type> [NOT NULL] [ENCODING <encoding_spec>] }
  [, ... ]
)
SERVER <server_name>
[ WITH ( <option> = <value> [, ... ] ) ]

Description

A foreign table acts as a proxy to an external data source for which access details are provided by a server object. A foreign table provides an interface for querying data from an external datasource in a similar way to a local table.

Parameters

Foreign Tables Refresh Options

Foreign Table Options for File Data Wrappers (delimited_file, parquet_file, and regex_parsed_file)

Additional Foreign Table Options for the delimited_file Data Wrapper

All delimited file parser options mentioned in https://docs.heavy.ai/loading-and-exporting-data/command-line/load-data#csv-tsv-import

Additional Foreign Table Options for the regex_parsed_file Data Wrapper

Foreign Table Options for ODBC Data Wrapper

ODBC HeavyConnect is currently in beta.

Example - Using the default local file server and default property

Create a foreign table that accesses a local CSV file at /home/my_user/data/csv/my_file.csv using this default server object.

CREATE FOREIGN TABLE my_csv_table (first_name TEXT, last_name TEXT ENCODING NONE) 
  SERVER default_local_delimited 
  WITH (file_path = '/home/my_user/data/csv/my_file.csv');

Example 2 - Using a custom local file server

Create a foreign table that accesses a local CSV file at path /home/my_user/data/csv/my_other_file.csv using the above my_csv_server object.

CREATE FOREIGN TABLE my_csv_table (first_name TEXT, last_name TEXT ENCODING NONE) 
  SERVER my_csv_server 
  WITH (file_path = 'my_other_file.csv');

The default "default_local_delimited" server object can also be used to accomplish the above. However, if you use a custom server object, you do not have to specify the full path when creating foreign tables.

Example 3 - Using the custom server and duration property

Create a foreign table that accesses a remote Parquet file named my_parquet_file, referenced by my_parquet_server object, for which content could change every 2 days.

CREATE FOREIGN TABLE my_parquet_table (first_name TEXT, last_name TEXT ENCODING NONE) 
  SERVER my_parquet_server 
  WITH (file_path = 'my_parquet_file', refresh_interval = '2D');

Example 4 - Using S3, custom S3 server, and the S3_Select option

CREATE FOREIGN TABLE my_s3_csv_table (first_name TEXT, last_name TEXT ENCODING NONE) 
  SERVER my_aws_server 
  WITH (s3_access_type = 's3_select', 
        file_path = 'my_csv_file', 
        refresh_update_type = 'append', 
        refresh_interval = '2D');

Use the CREATE USER MAPPING command to set access credentials when using S3. S3_Select requires set credentials even when using public buckets.

Additional Foreign Table Options for the default_local_raster Data Wrapper

Raster HeavyConnect is currently in beta.

ALTER FOREIGN TABLE

Update properties of existing foreign tables.

Syntax

ALTER FOREIGN TABLE <table_name>
    RENAME TO <new_table_name>

ALTER FOREIGN TABLE <table_name>
    RENAME COLUMN <column_name> TO <new_column_name>    

ALTER FOREIGN TABLE <table_name>
    [ SET (<option> = <value> [, ... ] ) ]

The following table options can be altered:

  • ALLOW_FILE_ROLL_OFF

  • BUFFER_SIZE

  • REFRESH_INTERVAL

  • REFRESH_START_DATE_TIME

  • REFRESH_TIMING_TYPE

  • REFRESH_UPDATE_TYPE

  • SQL_ORDER_BY

  • SQL_SELECT

Description

Allow users to update properties of existing foreign tables.

Parameters

Example - Change foreign table name

ALTER FOREIGN TABLE my_csv_table RENAME TO my_new_csv_table;

Example - Change foreign table column name

ALTER FOREIGN TABLE my_csv_table RENAME COLUMN first_name TO full_name; 

Example - Change the foreign table update type

ALTER FOREIGN TABLE my_csv_table SET (REFRESH_UPDATE_TYPE=APPEND’);

Example - Change the foreign table update schedule

ALTER FOREIGN TABLE my_csv_table 
  SET (REFRESH_TIMING_TYPE=‘SCHEDULED’, 
       REFRESH_START_DATE_TIME=2020-12-20 10:30’, 
       REFRESH_INTERVAL=‘1D’) ;

DROP FOREIGN TABLE

Delete a foreign table.

Syntax

DROP FOREIGN TABLE [ IF EXISTS ] <table_name>;

Description

Allows users to delete an existing foreign table.

Parameters

Example: Delete my_csv_table

DROP FOREIGN TABLE my_csv_table;

REFRESH FOREIGN TABLES

Refresh a foreign table.

Syntax

REFRESH FOREIGN TABLES <table_name>, <table_name> [ WITH ( <option> = <value> [, ... ] ) ];

Description

Allows users to do an on-demand refresh of one or more foreign tables.

Options

Parameters

User Mappings

A user mapping is an object that contains access credentials to an external datasource/foreign server. User mappings provide secure handling of user credentials when access to restricted external datasources or foreign servers is required. User mapping DDL commands can only be executed by super users or owners of referenced foreign servers. The following DDL commands are supported.

CREATE USER MAPPING

Create new user mappings.

Syntax

CREATE USER MAPPING [IF NOT EXISTS] FOR PUBLIC SERVER <server_name>
     WITH ( <option> = <value> [, ... ] )

Description

Allows users to create new user mappings. See related AWS documentation for information about AWS credentials.

Parameters

S3 User Mapping Options

AWS credentials that are configured on the server, such as IAM roles, can be used in place of user mappings. Enable this option with the allow-s3-server-privileges server configuration.

ODBC User Mapping Options

ODBC HeavyConnect is currently in beta.

Examples

Set up credentials for users to be able to query a foreign table (see related documentation for more details) that gets data from a previously created AWS S3 backed my_parquet_server,

CREATE USER MAPPING FOR PUBLIC SERVER my_parquet_server 
  WITH (aws_access_key_id = '1234', aws_secret_access_key = 'abcd');

DELETE USER MAPPING

Delete existing user mappings.

Syntax

DROP USER MAPPING [IF NOT EXISTS] FOR PUBLIC SERVER <server_name>

Description

Allows users to delete existing user mappings.

Parameters

Examples

Delete user mapping that was setup for my_parquet_server.

DROP USER MAPPING FOR PUBLIC SERVER my_parquet_server;

Last updated