Skip to content

Commit 02a79ad

Browse files
authored
chore: Convert Cube to table schema (#74)
* cube to table schema * lint fix * add test * export from browser and node
1 parent 385d478 commit 02a79ad

File tree

6 files changed

+264
-0
lines changed

6 files changed

+264
-0
lines changed

meerkat-browser/src/index.ts

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1 +1,3 @@
11
export * from './browser-cube-to-sql/browser-cube-to-sql';
2+
export { convertCubeStringToTableSchema };
3+
import { convertCubeStringToTableSchema } from '@devrev/meerkat-core';

meerkat-core/src/index.ts

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -14,6 +14,7 @@ export { FilterType } from './types/cube-types';
1414
export * from './types/cube-types/index';
1515
export * from './types/duckdb-serialization-types/index';
1616
export { BASE_TABLE_NAME } from './utils/base-ast';
17+
export * from './utils/cube-to-table-schema';
1718
export * from './utils/get-possible-nodes';
1819
export { meerkatPlaceholderReplacer } from './utils/meerkat-placeholder-replacer';
1920
export { memberKeyToSafeKey } from './utils/member-key-to-safe-key';
Lines changed: 47 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,47 @@
1+
import { convertCubeStringToTableSchema } from './cube-to-table-schema';
2+
describe('cube-to-table-schema', () => {
3+
it('Should convert to table schema', async () => {
4+
const files = [
5+
'cube(`users`, { sql_table: `public.users`, joins: {}, dimensions: { id: { sql: `id`, type: `number`, primary_key: true }, gender: { sql: `gender`, type: `string` }, city: { sql: `city`, type: `string` }, state: { sql: `state`, type: `string` }, first_name: { sql: `first_name`, type: `string` }, company: { sql: `company`, type: `string` }, last_name: { sql: `last_name`, type: `string` }, created_at: { sql: `created_at`, type: `time` } }, measures: { count: { type: `count` } }, pre_aggregations: {} });',
6+
'cube(`line_items`, { sql_table: `public.line_items`, joins: { orders: { sql: `${CUBE}.order_id = ${orders}.id`, relationship: `many_to_one` }, products: { sql: `${CUBE}.product_id = ${products}.id`, relationship: `many_to_one` } }, dimensions: { id: { sql: `id`, type: `number`, primary_key: true }, created_at: { sql: `created_at`, type: `time` } }, measures: { count: { type: `count` }, price: { sql: `price`, type: `sum` }, quantity: { sql: `quantity`, type: `sum` } }, pre_aggregations: {} });',
7+
];
8+
const outputTableSchemas = [
9+
{
10+
name: 'users',
11+
sql: 'public.users',
12+
measures: [{ name: 'count', sql: 'COUNT(*)', type: 'number' }],
13+
dimensions: [
14+
{ name: 'id', sql: 'id', type: 'number' },
15+
{ name: 'gender', sql: 'gender', type: 'string' },
16+
{ name: 'city', sql: 'city', type: 'string' },
17+
{ name: 'state', sql: 'state', type: 'string' },
18+
{ name: 'first_name', sql: 'first_name', type: 'string' },
19+
{ name: 'company', sql: 'company', type: 'string' },
20+
{ name: 'last_name', sql: 'last_name', type: 'string' },
21+
{ name: 'created_at', sql: 'created_at', type: 'time' },
22+
],
23+
},
24+
{
25+
name: 'line_items',
26+
sql: 'public.line_items',
27+
measures: [
28+
{ name: 'count', sql: 'COUNT(*)', type: 'number' },
29+
{ name: 'price', sql: 'SUM(price)', type: 'number' },
30+
{ name: 'quantity', sql: 'SUM(quantity)', type: 'number' },
31+
],
32+
dimensions: [
33+
{ name: 'id', sql: 'id', type: 'number' },
34+
{ name: 'created_at', sql: 'created_at', type: 'time' },
35+
],
36+
joins: [
37+
{ sql: '{MEERKAT}.order_id = orders.id' },
38+
{ sql: '{MEERKAT}.product_id = products.id' },
39+
],
40+
},
41+
];
42+
for (let i = 0; i < files.length; i++) {
43+
const tableSchema = convertCubeStringToTableSchema(files[i]);
44+
expect(tableSchema).toEqual(outputTableSchemas[i]);
45+
}
46+
});
47+
});
Lines changed: 136 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,136 @@
1+
import { DimensionType, Measure, TableSchema } from '../types/cube-types/table';
2+
3+
export type CubeMeasureType =
4+
| 'string'
5+
| 'string_array'
6+
| 'time'
7+
| 'number'
8+
| 'number_array'
9+
| 'boolean'
10+
| 'count'
11+
| 'count_distinct'
12+
| 'count_distinct_approx'
13+
| 'sum'
14+
| 'avg'
15+
| 'min'
16+
| 'max';
17+
18+
interface CubeSchema {
19+
name: string;
20+
object: {
21+
sql_table: string;
22+
measures: {
23+
[key: string]: CubeMeasure;
24+
};
25+
dimensions: {
26+
[key: string]: {
27+
sql: string;
28+
type: DimensionType;
29+
};
30+
};
31+
joins?: {
32+
[key: string]: {
33+
sql: string;
34+
};
35+
};
36+
};
37+
}
38+
const cube = (name: any, object: any) => ({ name, object });
39+
export function convertCubeStringToTableSchema(
40+
file: string
41+
): TableSchema | null {
42+
// replace ${...} with ...
43+
let replacedFile = file.replace(/\${(.*?)}/g, (match, variable) => variable);
44+
45+
// replace CUBE with MEERKAT
46+
replacedFile = replacedFile.replace(/CUBE/g, '{MEERKAT}');
47+
const { name, object } = eval(replacedFile);
48+
return convertCubeToTableSchema({ name, object });
49+
}
50+
51+
function convertCubeToTableSchema({
52+
name,
53+
object,
54+
}: CubeSchema): TableSchema | null {
55+
const resObj: TableSchema = {
56+
name,
57+
sql: object.sql_table,
58+
measures: [],
59+
dimensions: [],
60+
};
61+
const dimensions = object.dimensions;
62+
const measures = object.measures;
63+
64+
// convert dimensions and measures
65+
for (const key in dimensions) {
66+
resObj.dimensions.push({
67+
name: key,
68+
sql: dimensions[key].sql,
69+
type: dimensions[key].type,
70+
});
71+
}
72+
for (const key in measures) {
73+
resObj.measures.push({ name: key, ...convertMeasure(measures[key]) });
74+
}
75+
76+
// convert joins
77+
if (object.joins && Object.keys(object.joins).length > 0) {
78+
resObj.joins = [];
79+
for (const joinName in object.joins) {
80+
const join = object.joins[joinName];
81+
resObj.joins.push({
82+
sql: join.sql,
83+
});
84+
}
85+
}
86+
return resObj;
87+
}
88+
interface CubeMeasure {
89+
sql?: string;
90+
type: CubeMeasureType;
91+
}
92+
93+
function convertMeasure(measure: CubeMeasure): Pick<Measure, 'sql' | 'type'> {
94+
switch (measure.type) {
95+
case 'count':
96+
return {
97+
sql: measure.sql ? `COUNT(${measure.sql})` : 'COUNT(*)',
98+
type: 'number',
99+
};
100+
case 'count_distinct':
101+
return {
102+
sql: `COUNT(DISTINCT ${measure.sql})`,
103+
type: 'number',
104+
};
105+
case 'count_distinct_approx':
106+
return {
107+
sql: `APPROX_COUNT_DISTINCT(${measure.sql})`,
108+
type: 'number',
109+
};
110+
case 'sum':
111+
return {
112+
sql: `SUM(${measure.sql})`,
113+
type: 'number',
114+
};
115+
case 'avg':
116+
return {
117+
sql: `AVG(${measure.sql})`,
118+
type: 'number',
119+
};
120+
case 'min':
121+
return {
122+
sql: `MIN(${measure.sql})`,
123+
type: 'number',
124+
};
125+
case 'max':
126+
return {
127+
sql: `MAX(${measure.sql})`,
128+
type: 'number',
129+
};
130+
default:
131+
return {
132+
sql: measure.sql ?? '',
133+
type: measure.type,
134+
};
135+
}
136+
}
Lines changed: 76 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,76 @@
1+
import { convertCubeStringToTableSchema } from '@devrev/meerkat-core';
2+
import { cubeQueryToSQL } from '../cube-to-sql/cube-to-sql';
3+
import { duckdbExec } from '../duckdb-exec';
4+
5+
export const CREATE_PRODUCTS_TABLE = `
6+
CREATE TABLE products (
7+
id INTEGER,
8+
name VARCHAR,
9+
description VARCHAR,
10+
created_at TIMESTAMP,
11+
supplier_id INTEGER
12+
);
13+
`;
14+
export const CREATE_SUPPLIERS_TABLE = `
15+
CREATE TABLE suppliers (
16+
id INTEGER,
17+
address VARCHAR,
18+
email VARCHAR,
19+
company VARCHAR,
20+
created_at TIMESTAMP
21+
);
22+
`;
23+
24+
export const INPUT_PRODUCTS_DATA = `
25+
INSERT INTO products VALUES
26+
(1, 'Pencil', 'It is a pencil', '2022-01-01', 1),
27+
(2, 'Pen', 'It is a pen', '2022-01-02', 1),
28+
(3, 'Eraser', 'It is an eraser', '2022-02-01', 2);
29+
`;
30+
31+
export const INPUT_SUPPLIERS_DATA = `
32+
INSERT INTO suppliers VALUES
33+
(1, '123 Main St', '[email protected]', 'john doe', '2022-01-01'),
34+
(2, '456 Main St', '[email protected]', 'steve smith', '2022-01-02');
35+
`;
36+
37+
describe('Cube Schema to SQL', () => {
38+
beforeAll(async () => {
39+
await duckdbExec(CREATE_PRODUCTS_TABLE);
40+
await duckdbExec(CREATE_SUPPLIERS_TABLE);
41+
await duckdbExec(INPUT_PRODUCTS_DATA);
42+
await duckdbExec(INPUT_SUPPLIERS_DATA);
43+
});
44+
45+
it('Should be able to execute sql query from cube string', async () => {
46+
const productsFile =
47+
"cube('products', { sql_table: 'select * from products', joins: { suppliers: { sql: `products.supplier_id = ${suppliers}.id`, relationship: 'many_to_one' } }, dimensions: { id: { sql: 'id', type: 'number', primary_key: true }, name: { sql: 'name', type: 'string' }, description: { sql: 'description', type: 'string' }, created_at: { sql: 'products.created_at', type: 'time' } }, measures: { count: { type: 'count' } }, pre_aggregations: {} });";
48+
const suppliersFile =
49+
"cube('suppliers', { sql_table: 'select * from suppliers', joins: {}, dimensions: { id: { sql: 'id', type: 'number', primary_key: true }, address: { sql: 'address', type: 'string' }, email: { sql: 'email', type: 'string' }, company: { sql: 'company', type: 'string' }, created_at: { sql: 'suppliers.created_at', type: 'time' } }, measures: { count: { type: 'count' } }, pre_aggregations: {} });";
50+
const productsSchema = convertCubeStringToTableSchema(productsFile);
51+
const suppliersSchema = convertCubeStringToTableSchema(suppliersFile);
52+
const query = {
53+
measures: ['products.count'],
54+
filters: [],
55+
dimensions: ['suppliers.created_at', 'products.created_at'],
56+
joinPaths: [
57+
[
58+
{
59+
left: 'products',
60+
on: 'supplier_id',
61+
right: 'suppliers',
62+
},
63+
],
64+
],
65+
};
66+
const sql = await cubeQueryToSQL(query, [productsSchema, suppliersSchema]);
67+
console.info(`SQL for Simple Cube Query: `, sql);
68+
const output = await duckdbExec(sql);
69+
const parsedOutput = JSON.parse(JSON.stringify(output));
70+
console.info('parsedOutput', parsedOutput);
71+
expect(sql).toEqual(
72+
'SELECT COUNT(*) AS products__count , suppliers__created_at, products__created_at FROM (SELECT *, products.created_at AS products__created_at FROM (select * from products) AS products LEFT JOIN (SELECT *, suppliers.created_at AS suppliers__created_at FROM (select * from suppliers) AS suppliers) AS suppliers ON products.supplier_id = suppliers.id) AS MEERKAT_GENERATED_TABLE GROUP BY suppliers__created_at, products__created_at'
73+
);
74+
expect(parsedOutput).toHaveLength(3);
75+
});
76+
});

meerkat-node/src/index.ts

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,3 +1,5 @@
11
export * from './cube-to-sql/cube-to-sql';
22
export * from './duckdb-singleton';
33
export * from './node-sql-to-serialization';
4+
export { convertCubeStringToTableSchema };
5+
import { convertCubeStringToTableSchema } from '@devrev/meerkat-core';

0 commit comments

Comments
 (0)