@dataform/sql
Version:
General purpose SQL helper functions for building queries in JS across dialects.
476 lines (465 loc) • 16.9 kB
JavaScript
class Select {
constructor(query) {
this.query = query;
}
static create(query) {
return new Select(query);
}
toString() {
return this.query;
}
}
function build(selectOrBuilder) {
if (typeof selectOrBuilder === "string") {
return Select.create(selectOrBuilder);
}
if (selectOrBuilder instanceof Select) {
return selectOrBuilder;
}
return selectOrBuilder.build();
}
function indent(value) {
return String(value)
.split("\n")
.map(row => ` ${row}`)
.join("\n");
}
class AggregateBuilder {
constructor(from) {
this.from = from;
this.selectedDimensions = {};
this.selectedMetrics = {};
this.whereClauses = [];
}
metrics(select) {
this.selectedMetrics = Object.assign(Object.assign({}, this.selectedMetrics), select);
return this;
}
dimensions(select) {
this.selectedDimensions = Object.assign(Object.assign({}, this.selectedDimensions), select);
return this;
}
ordering(ordering) {
this.selectedOrdering = ordering;
return this;
}
where(...wheres) {
wheres.forEach(where => this.whereClauses.push(where));
return this;
}
limit(limit) {
this.selectedLimit = limit;
return this;
}
build() {
const hasDimensions = Object.keys(this.selectedDimensions).length > 0;
const hasMetrics = Object.keys(this.selectedMetrics).length > 0;
const whereExpression = this.whereClauses.length > 0 ? `\nwhere\n${indent(this.whereClauses.join(" and\n"))}` : "";
const orderingExpression = this.selectedOrdering
? `\norder by\n ${this.selectedOrdering.expression} ${this.selectedOrdering.descending ? "desc" : "asc"}`
: "";
const limitExpression = this.selectedLimit ? `\nlimit ${this.selectedLimit}` : "";
return Select.create(`(\n${indent(`select\n` +
(!hasDimensions && !hasMetrics ? indent("*") : "") +
`${Object.keys(this.selectedDimensions)
.map(alias => indent(`${this.selectedDimensions[alias]} as ${alias}`))
.join(",\n")}${hasDimensions && hasMetrics ? ",\n" : ""}` +
`${Object.keys(this.selectedMetrics)
.map(alias => indent(`${this.selectedMetrics[alias]} as ${alias}`))
.join(",\n")}\n` +
`from\n` +
`${indent(build(this.from))}` +
`${whereExpression}` +
`${hasDimensions
? `\ngroup by ${Array.from(new Array(Object.keys(this.selectedDimensions).length).keys())
.map(i => i + 1)
.join(", ")}`
: ""}` +
`${orderingExpression}` +
`${limitExpression}`)}\n)`);
}
}
class FromBuilder {
constructor(from) {
this.from = from;
this.columns = {};
this.whereClauses = [];
}
select(select) {
if (select instanceof Array) {
select.forEach(value => (this.columns[value] = value));
}
else {
this.columns = Object.assign(Object.assign({}, this.columns), select);
}
return this;
}
ordering(ordering) {
this.selectedOrdering = ordering;
return this;
}
where(...wheres) {
wheres.forEach(where => this.whereClauses.push(where));
return this;
}
limit(limit) {
this.selectedLimit = limit;
return this;
}
build() {
const hasColumns = Object.keys(this.columns).length > 0;
const whereExpression = this.whereClauses.length > 0 ? `\nwhere\n${indent(this.whereClauses.join(" and\n "))}` : "";
const orderingExpression = this.selectedOrdering
? `\norder by\n ${this.selectedOrdering.expression} ${this.selectedOrdering.descending ? "desc" : "asc"}`
: "";
const limitExpression = this.selectedLimit ? `\nlimit ${this.selectedLimit}` : "";
return Select.create(`(\n${indent(`select\n` +
(hasColumns
? `${Object.keys(this.columns)
.map(alias => ` ${this.columns[alias]} as ${alias}`)
.join(",\n")}`
: indent("*")) +
`\nfrom\n` +
`${indent(build(this.from))}` +
`${whereExpression}` +
`${orderingExpression}` +
`${limitExpression}`)}\n)`);
}
}
class JoinBuilder {
constructor(joins) {
this.joins = joins;
}
build() {
const baseAlias = Object.keys(this.joins).find(key => !!key || key === "base");
const baseSelect = this.joins[baseAlias];
const joinAliases = Object.keys(this.joins).filter(alias => alias !== baseAlias);
return Select.create(`${indent(build(baseSelect.select))} ${baseAlias}
${joinAliases
.map(alias => `${this.joins[alias].type} join
${build(this.joins[alias].select)} ${alias} ${!!this.joins[alias].on
? `on (${baseAlias}.${this.joins[alias].on[0]} = ${alias}.${this.joins[alias].on[1]})`
: ""}`)
.join(`\n`)}`);
}
}
class JSONBuilder {
constructor(sql, data) {
this.sql = sql;
this.data = data;
}
build() {
return Select.create(`(
${indent(this.data
.map(row => `select ${Object.keys(row)
.map(alias => `${this.sql.literal(row[alias])} as ${alias}`)
.join(", ")}`)
.join(`\nunion all\n`))}
)`);
}
}
class UnionBuilder {
constructor(selects) {
this.selects = selects;
}
build() {
return Select.create(`(
${indent(this.selects.map(select => build(select).query).join(`
union all
`))}
)`);
}
}
class WithBuilder {
constructor(withs) {
this.withs = withs;
}
select(select) {
return Select.create((Object.keys(this.withs).length > 0
? `with
${Object.keys(this.withs)
.map(key => `${key} as (
${indent(build(this.withs[key]))}
)`)
.join(",\n")}
`
: "") + build(select).query);
}
}
class Timestamps {
constructor(dialect) {
this.dialect = dialect;
}
fromMillis(timestampMillis) {
if (this.dialect === "snowflake") {
return `to_timestamp(${timestampMillis}, 3)`;
}
if (this.dialect === "postgres" || this.dialect === "redshift") {
return `timestamp 'epoch' + (${timestampMillis}) * interval '0.001 second'`;
}
return `timestamp_millis(${timestampMillis.toString()})`;
}
truncate(timestamp, timestampUnit) {
if (this.dialect === "snowflake") {
return `date_trunc(${timestampUnit}, ${timestamp})`;
}
if (this.dialect === "postgres" || this.dialect === "redshift") {
return `date_trunc('${timestampUnit}', ${timestamp})`;
}
return `timestamp_trunc(${timestamp}, ${timestampUnit})`;
}
toMillis(timestamp) {
if (this.dialect === "snowflake") {
return `date_part(epoch_milliseconds, ${timestamp})`;
}
if (this.dialect === "postgres" || this.dialect === "redshift") {
return `extract('epoch' from ${timestamp})::bigint * 1000`;
}
return `unix_millis(${timestamp})`;
}
currentUTC() {
if (this.dialect === "postgres" || this.dialect === "redshift") {
return "current_timestamp::timestamp";
}
if (this.dialect === "snowflake") {
return "convert_timezone('UTC', current_timestamp())::timestamp";
}
if (this.dialect === "mssql") {
return "CURRENT_TIMESTAMP";
}
return "current_timestamp()";
}
diff(datePart, start, end) {
if (this.dialect === "standard") {
return `timestamp_diff(${end}, ${start}, ${datePart})`;
}
if (this.dialect === "snowflake" || this.dialect === "mssql" || this.dialect === "redshift") {
return `datediff(${datePart}, ${start}, ${end})`;
}
if (this.dialect === "postgres") {
if (datePart.toLowerCase() === "day") {
return `date_part('day', ${end} - ${start})`;
}
if (datePart.toLowerCase() === "hour") {
return `24 * date_part('day', ${end} - ${start}) + date_part('hour', ${end} - ${start})`;
}
if (datePart.toLowerCase() === "minute") {
return `24 * date_part('day', ${end} - ${start}) + 60 * date_part('hour', ${end} - ${start}) + date_part('minute', ${end} - ${start})`;
}
if (datePart.toLowerCase() === "second") {
return `24 * date_part('day', ${end} - ${start}) + 60 * date_part('hour', ${end} - ${start}) + 60 * date_part('minute', ${end} - ${start}) + date_part('second', ${end} - ${start})`;
}
if (datePart.toLowerCase() === "millisecond") {
return `24 * date_part('day', ${end} - ${start}) + 60 * date_part('hour', ${end} - ${start}) + 60 * date_part('minute', ${end} - ${start}) + 1000 * date_part('second', ${end} - ${start}) + date_part('millisecond', ${end} - ${start})`;
}
}
}
add(timestamp, units, datePart) {
if (this.dialect === "standard") {
return `timestamp_add(${timestamp}, interval ${units} ${datePart})`;
}
if (this.dialect === "postgres") {
return `${timestamp} + interval '1 ${datePart}' * ${units}`;
}
if (this.dialect === "snowflake") {
return `timestampadd(${datePart}, ${units}, ${timestamp})`;
}
return `dateadd(${datePart}, ${units}, ${timestamp})`;
}
}
class Sql {
constructor(dialect = "standard") {
this.dialect = dialect;
this.timestamps = new Timestamps(dialect);
}
literal(value) {
if (value === null) {
return "null";
}
if (typeof value === "string") {
return `'${value}'`;
}
return String(value);
}
not(expression) {
return `not (${expression})`;
}
countDistinct(expression) {
return `count(distinct ${expression})`;
}
conditional(condition, then, otherwise = "null") {
if (this.dialect === "snowflake") {
return `iff(${condition}, ${then}, ${otherwise || "null"})`;
}
if (this.dialect === "postgres" || this.dialect === "redshift") {
return `case when ${condition} then ${then} else ${otherwise} end`;
}
return `if(${condition}, ${then}, ${otherwise || "null"})`;
}
equals(expression, expected) {
if (expected.trim().toLowerCase() === "null") {
return `${expression} is null`;
}
return `${expression} = ${expected}`;
}
gt(left, right) {
return `${left} > ${right}`;
}
gteq(left, right) {
return `${left} >= ${right}`;
}
lt(left, right) {
return `${left} < ${right}`;
}
lteq(left, right) {
return `${left} <= ${right}`;
}
in(expression, values) {
if (values.length === 0) {
return "false";
}
const containsNull = values.find(value => value.toLowerCase() === "null");
const nonNullValues = values.filter(value => value.toLowerCase() !== "null");
const ors = [];
if (containsNull) {
ors.push(this.equals(expression, "null"));
}
if (nonNullValues.length > 0) {
ors.push(`${expression} in (${values.join(", ")})`);
}
return this.or(ors);
}
sum(expression) {
return `sum(${expression})`;
}
min(expression) {
return `min(${expression})`;
}
max(expression) {
return `max(${expression})`;
}
avg(expression) {
return `avg(${expression})`;
}
count() {
return `sum(1)`;
}
coalesce(...expressions) {
return `coalesce(${expressions.join(", ")})`;
}
or(expressions) {
return `(${expressions.join(" or ")})`;
}
and(expressions) {
return expressions.join(" and ");
}
withWrappingBrackets(expression) {
return `(${expression})`;
}
safeDivide(numerator, denominator) {
return `${numerator} / nullif(${denominator}, 0)`;
}
asTimestamp(castableToTimestamp) {
return `cast(${castableToTimestamp} as timestamp)`;
}
asString(castableToString) {
if (this.dialect === "postgres" || this.dialect === "redshift") {
return `cast(${castableToString} as varchar)`;
}
return `cast(${castableToString} as string)`;
}
surrogateKey(columnNames) {
const columnsAsStrings = columnNames.map(id => this.asString(id)).join(`,`);
if (this.dialect === "standard") {
return this.asString(`farm_fingerprint(concat(${columnsAsStrings}))`);
}
if (this.dialect === "mssql") {
return this.asString(`hashbytes("md5", (concat(${columnsAsStrings})))`);
}
return this.asString(`md5(concat(${columnsAsStrings}))`);
}
windowFunction(name, value, ignoreNulls = false, windowSpecification) {
const partitionFieldsAsString = windowSpecification.partitionFields
? [...windowSpecification.partitionFields].join(`, `)
: "";
const orderFieldsAsString = windowSpecification.orderFields
? [...windowSpecification.orderFields].join(`, `)
: "";
if (this.dialect === "standard" || this.dialect === "mssql" || this.dialect === "snowflake") {
return `${name}(${value} ${ignoreNulls ? `ignore nulls` : ``}) over (${windowSpecification.partitionFields ? `partition by ${partitionFieldsAsString}` : ``} ${windowSpecification.orderFields ? `order by ${orderFieldsAsString}` : ``} ${windowSpecification.frameClause ? windowSpecification.frameClause : ``})`;
}
const requiresFrame = [
"avg",
"count",
"first_value",
"last_value",
"max",
"min",
"nth_value",
"stddev_samp",
"stddev_pop",
"stddev",
"sum",
"variance",
"var_samp",
"var_pop"
].includes(name.toLowerCase());
if (this.dialect === "redshift") {
return `${name}(${value} ${ignoreNulls ? `ignore nulls` : ``}) over (${windowSpecification.partitionFields ? `partition by ${partitionFieldsAsString}` : ``} ${windowSpecification.orderFields ? `order by ${orderFieldsAsString}` : ``} ${windowSpecification.orderFields
? windowSpecification.frameClause
? windowSpecification.frameClause
: requiresFrame
? `rows between unbounded preceding and unbounded following`
: ``
: ``})`;
}
if (this.dialect === "postgres") {
return `${name}(${value}) over (${windowSpecification.partitionFields ? `partition by ${partitionFieldsAsString}` : ``} ${windowSpecification.orderFields || ignoreNulls ? `order by` : ``} ${ignoreNulls ? `case when ${value} is not null then 0 else 1 end asc` : ``} ${orderFieldsAsString && ignoreNulls ? `,` : ``} ${orderFieldsAsString} ${windowSpecification.orderFields
? windowSpecification.frameClause
? windowSpecification.frameClause
: requiresFrame
? `rows between unbounded preceding and unbounded following`
: ``
: ``})`;
}
}
stringAgg(field, delimiter = ",") {
if (this.dialect === "snowflake" || this.dialect === "redshift") {
return `listagg(${field}, '${delimiter}')`;
}
return `string_agg(${field}, '${delimiter}')`;
}
json(data) {
return new JSONBuilder(this, data);
}
join(joins) {
return new JoinBuilder(joins);
}
with(withs) {
return new WithBuilder(withs);
}
union(...selects) {
return new UnionBuilder(selects);
}
aggregate(from) {
return new AggregateBuilder(from);
}
from(from) {
return new FromBuilder(from);
}
}
const getDefaultDialect = () => {
const dataformWarehouse = global.dataform.projectConfig.warehouse;
if (!dataformWarehouse) {
return "standard";
}
return {
bigquery: "standard",
redshift: "redshift",
postgres: "postgres",
snowflake: "snowflake",
sqldatawarehouse: "mssql"
}[dataformWarehouse];
};
module.exports = (dialect = getDefaultDialect()) => new Sql(dialect);
;