Database

MSSQL


Microsoft SQL Server is a proprietary relational database management system developed by Microsoft.

The SQL Server Wrapper allows you to read data from Microsoft SQL Server within your Postgres database.

Supported Data Types

Postgres TypeSQL Server Type
booleanbit
chartinyint
smallintsmallint
realfloat(24)
integerint
double precisionfloat(53)
bigintbigint
numericnumeric/decimal
textvarchar/char/text
datedate
timestampdatetime/datetime2/smalldatetime
timestamptzdatetime/datetime2/smalldatetime

Preparation

Before you can query SQL Server, you need to enable the Wrappers extension and store your credentials in Postgres.

Enable Wrappers

Make sure the wrappers extension is installed on your database:


_10
create extension if not exists wrappers with schema extensions;

Enable the SQL Server Wrapper

Enable the mssql_wrapper FDW:


_10
create foreign data wrapper mssql_wrapper
_10
handler mssql_fdw_handler
_10
validator mssql_fdw_validator;

Store your credentials (optional)

By default, Postgres stores FDW credentials inside 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.


_10
-- Save your SQL Server connection string in Vault and retrieve the `key_id`
_10
insert into vault.secrets (name, secret)
_10
values (
_10
'mssql',
_10
'Server=localhost,1433;User=sa;Password=my_password;Database=master;IntegratedSecurity=false;TrustServerCertificate=true;encrypt=DANGER_PLAINTEXT;ApplicationName=wrappers'
_10
)
_10
returning key_id;

The connection string is an ADO.NET connection string, which specifies connection parameters in semicolon-delimited string.

Supported parameters

All parameter keys are handled case-insensitive.

ParameterAllowed ValuesDescription
Server<string>The name or network address of the instance of SQL Server to which to connect. Format: host,port
User<string>The SQL Server login account.
Password<string>The password for the SQL Server account logging on.
Database<string>The name of the database.
IntegratedSecurityfalseWindows/Kerberos authentication and SQL authentication.
TrustServerCertificatetrue, falseSpecifies whether the driver trusts the server certificate when connecting using TLS.
Encrypttrue, false, DANGER_PLAINTEXTSpecifies whether the driver uses TLS to encrypt communication.
ApplicationName<string>Sets the application name for the connection.

Connecting to SQL Server

We need to provide Postgres with the credentials to connect to SQL Server. We can do this using the create server command:


_10
create server mssql_server
_10
foreign data wrapper mssql_wrapper
_10
options (
_10
conn_string_id '<key_ID>' -- The Key ID from above.
_10
);

Create a schema

We recommend creating a schema to hold all the foreign tables:


_10
create schema if not exists mssql;

Options

The full list of foreign table options are below:

  • table - Source table or view name in SQL Server, required.

This can also be a subquery enclosed in parentheses, for example,


_10
table '(select * from users where id = 42 or id = 43)'

Entities

SQL Server Tables

This is an object representing SQL Server tables and views.

Ref: Microsoft SQL Server docs

Operations

ObjectSelectInsertUpdateDeleteTruncate
table/view

Usage


_10
create foreign table mssql.users (
_10
id bigint,
_10
name text,
_10
dt timestamp
_10
)
_10
server mssql_server
_10
options (
_10
table 'users'
_10
);

Notes

  • Supports both tables and views as data sources
  • Can use subqueries in the table option
  • Query pushdown supported for:
    • where clauses
    • order by clauses
    • limit clauses
  • See Data Types section for type mappings between PostgreSQL and SQL Server

Query Pushdown Support

This FDW supports where, order by and limit clause pushdown.

Examples

Basic Example

First, create a source table in SQL Server:


_11
-- Run below SQLs on SQL Server to create source table
_11
create table users (
_11
id bigint,
_11
name varchar(30),
_11
dt datetime2
_11
);
_11
_11
-- Add some test data
_11
insert into users(id, name, dt) values (42, 'Foo', '2023-12-28');
_11
insert into users(id, name, dt) values (43, 'Bar', '2023-12-27');
_11
insert into users(id, name, dt) values (44, 'Baz', '2023-12-26');

Then create and query the foreign table in PostgreSQL:


_11
create foreign table mssql.users (
_11
id bigint,
_11
name text,
_11
dt timestamp
_11
)
_11
server mssql_server
_11
options (
_11
table 'users'
_11
);
_11
_11
select * from mssql.users;

Remote Subquery Example

Create a foreign table using a subquery:


_11
create foreign table mssql.users_subquery (
_11
id bigint,
_11
name text,
_11
dt timestamp
_11
)
_11
server mssql_server
_11
options (
_11
table '(select * from users where id = 42 or id = 43)'
_11
);
_11
_11
select * from mssql.users_subquery;