Adapters

Schema adapters

A schema adapter allows Calcite to read particular kind of data, presenting the data as tables within a schema.

Other language interfaces

Engines

Many projects and products use Apache Calcite for SQL parsing, query optimization, data virtualization/federation, and materialized view rewrite. Some of them are listed on the “powered by Calcite” page.

Drivers

A driver allows you to connect to Calcite from your application.

The JDBC driver is powered by Avatica. Connections can be local or remote (JSON over HTTP or Protobuf over HTTP).

The basic form of the JDBC connect string is

jdbc:calcite:property=value;property2=value2

where property, property2 are properties as described below. (Connect strings are compliant with OLE DB Connect String syntax, as implemented by Avatica’s ConnectStringParser.)

JDBC connect string parameters

Property Description
approximateDecimal Whether approximate results from aggregate functions on DECIMAL types are acceptable
approximateDistinctCount Whether approximate results from COUNT(DISTINCT ...) aggregate functions are acceptable
approximateTopN Whether approximate results from “Top N” queries * (ORDER BY aggFun() DESC LIMIT n) are acceptable
caseSensitive Whether identifiers are matched case-sensitively. If not specified, value from lex is used.
conformance SQL conformance level. Values: DEFAULT (the default, similar to PRAGMATIC_2003), ORACLE_10, ORACLE_12, PRAGMATIC_99, PRAGMATIC_2003, STRICT_92, STRICT_99, STRICT_2003, SQL_SERVER_2008.
createMaterializations Whether Calcite should create materializations. Default false.
defaultNullCollation How NULL values should be sorted if neither NULLS FIRST nor NULLS LAST are specified in a query. The default, HIGH, sorts NULL values the same as Oracle.
druidFetch How many rows the Druid adapter should fetch at a time when executing SELECT queries.
forceDecorrelate Whether the planner should try de-correlating as much as possible. Default true.
fun Collection of built-in functions and operators. Valid values: “standard” (the default), “oracle”.
lex Lexical policy. Values are ORACLE (default), MYSQL, MYSQL_ANSI, SQL_SERVER, JAVA.
materializationsEnabled Whether Calcite should use materializations. Default false.
model URI of the JSON model file.
parserFactory Parser factory. The name of a class that implements SqlParserImplFactory and has a public default constructor or an INSTANCE constant.
quoting How identifiers are quoted. Values are DOUBLE_QUOTE, BACK_QUOTE, BRACKET. If not specified, value from lex is used.
quotedCasing How identifiers are stored if they are quoted. Values are UNCHANGED, TO_UPPER, TO_LOWER. If not specified, value from lex is used.
schema Name of initial schema.
schemaFactory Schema factory. The name of a class that implements SchemaFactory and has a public default constructor or an INSTANCE constant. Ignored if model is specified.
schemaType Schema type. Value must be “MAP” (the default), “JDBC”, or “CUSTOM” (implicit if schemaFactory is specified). Ignored if model is specified.
spark Specifies whether Spark should be used as the engine for processing that cannot be pushed to the source system. If false (the default), Calcite generates code that implements the Enumerable interface.
timeZone Time zone, for example “gmt-3”. Default is the JVM’s time zone.
typeSystem Type system. The name of a class that implements RelDataTypeSystem and has a public default constructor or an INSTANCE constant.
unquotedCasing How identifiers are stored if they are not quoted. Values are UNCHANGED, TO_UPPER, TO_LOWER. If not specified, value from lex is used.

To make a connection to a single schema based on a built-in schema type, you don’t need to specify a model. For example,

jdbc:calcite:schemaType=JDBC; schema.jdbcUser=SCOTT; schema.jdbcPassword=TIGER; schema.jdbcUrl=jdbc:hsqldb:res:foodmart

creates a connection with a schema mapped via the JDBC schema adapter to the foodmart database.

Similarly, you can connect to a single schema based on a user-defined schema adapter. For example,

jdbc:calcite:schemaFactory=org.apache.calcite.adapter.cassandra.CassandraSchemaFactory; schema.host=localhost; schema.keyspace=twissandra

makes a connection to the Cassandra adapter, equivalent to writing the following model file:

{
  "version": "1.0",
  "defaultSchema": "foodmart",
  "schemas": [
    {
      type: 'custom',
      name: 'twissandra',
      factory: 'org.apache.calcite.adapter.cassandra.CassandraSchemaFactory',
      operand: {
        host: 'localhost',
        keyspace: 'twissandra'
      }
    }
  ]
}

Note how each key in the operand section appears with a schema. prefix in the connect string.