diff --git a/package.json b/package.json index 45eecc49..e71e00bf 100644 --- a/package.json +++ b/package.json @@ -71,30 +71,30 @@ "properties": { "vscode-db2i.sqlFormat.identifierCase": { "type": "string", - "description": "SQL identifiers", + "description": "Format SQL identifiers into a certain case", "default": "preserve", "enum": [ "lower", "upper", "preserve" - ], - "enumDescriptions": [ - "Format SQL identifiers in lowercase", - "Format SQL identifiers in uppercase", - "Preserve the current formatting of SQL identifiers" ] }, "vscode-db2i.sqlFormat.keywordCase": { "type": "string", - "description": "SQL keywords", + "description": "Format SQL keywords into a certain case", "default": "lower", "enum": [ "lower", "upper" - ], - "enumDescriptions": [ - "Format reserved SQL keywords in lowercase", - "Format reserved SQL keywords in uppercase" + ] + }, + "vscode-db2i.sqlFormat.spaceBetweenStatements": { + "type": "string", + "description": "Add space between statements.", + "default": "true", + "enum": [ + "true", + "false" ] } } diff --git a/src/contributes.json b/src/contributes.json index 7368a32f..4471f50c 100644 --- a/src/contributes.json +++ b/src/contributes.json @@ -30,30 +30,30 @@ "properties": { "vscode-db2i.sqlFormat.identifierCase": { "type": "string", - "description": "SQL identifiers", + "description": "Format SQL identifiers into a certain case", "default": "preserve", "enum": [ "lower", "upper", "preserve" - ], - "enumDescriptions": [ - "Format SQL identifiers in lowercase", - "Format SQL identifiers in uppercase", - "Preserve the current formatting of SQL identifiers" ] }, "vscode-db2i.sqlFormat.keywordCase": { "type": "string", - "description": "SQL keywords", + "description": "Format SQL keywords into a certain case", "default": "lower", "enum": [ "lower", "upper" - ], - "enumDescriptions": [ - "Format reserved SQL keywords in lowercase", - "Format reserved SQL keywords in uppercase" + ] + }, + "vscode-db2i.sqlFormat.spaceBetweenStatements": { + "type": "string", + "description": "Add space between statements.", + "default": "true", + "enum": [ + "true", + "false" ] } } diff --git a/src/language/providers/formatProvider.ts b/src/language/providers/formatProvider.ts index 8741cdb3..af0350d7 100644 --- a/src/language/providers/formatProvider.ts +++ b/src/language/providers/formatProvider.ts @@ -1,13 +1,20 @@ import { Position, Range, TextEdit, languages } from "vscode"; import Statement from "../../database/statement"; +import { formatSql, CaseOptions } from "../sql/formatter"; +import Configuration from "../../configuration"; export const formatProvider = languages.registerDocumentFormattingEditProvider({language: `sql`}, { async provideDocumentFormattingEdits(document, options, token) { - const formatted = Statement.format( + const identifierCase: CaseOptions = (Configuration.get(`sqlFormat.identifierCase`) || `preserve`); + const keywordCase: CaseOptions = (Configuration.get(`sqlFormat.keywordCase`) || `lower`); + const spaceBetweenStatements: string = (Configuration.get(`sqlFormat.spaceBetweenStatements`) || `false`); + const formatted = formatSql( document.getText(), { - useTabs: !options.insertSpaces, - tabWidth: options.tabSize, + indentWidth: options.tabSize, + identifierCase, + keywordCase, + spaceBetweenStatements: spaceBetweenStatements === `true` } ); diff --git a/src/language/sql/formatter.ts b/src/language/sql/formatter.ts new file mode 100644 index 00000000..cdcd4f80 --- /dev/null +++ b/src/language/sql/formatter.ts @@ -0,0 +1,194 @@ +import Document from "./document"; +import { StatementGroup, StatementType, StatementTypeWord, Token } from "./types"; +import SQLTokeniser from "./tokens"; + +export declare type CaseOptions = `preserve` | `upper` | `lower`; + +export interface FormatOptions { + indentWidth?: number; // Defaults to 4 + keywordCase?: CaseOptions; + identifierCase?: CaseOptions; + newLineLists?: boolean; + spaceBetweenStatements?: boolean +} + +const SINGLE_LINE_STATEMENT_TYPES: StatementType[] = [StatementType.Create, StatementType.Declare, StatementType.Set, StatementType.Delete, StatementType.Call, StatementType.If, StatementType.End]; + +export function formatSql(textDocument: string, options: FormatOptions = {}): string { + let result: string[] = []; + let document = new Document(textDocument); + const statementGroups: StatementGroup[] = document.getStatementGroups(); + + const eol = textDocument.includes(`\r\n`) ? `\r\n` : `\n`; + let prevType = StatementType.Unknown; + + for (const statementGroup of statementGroups) { + let currentIndent = 0; + for (let i = 0; i < statementGroup.statements.length; i++) { + const statement = statementGroup.statements[i]; + const withBlocks = SQLTokeniser.createBlocks(statement.tokens); + + if (statement.isCompoundEnd() || statement.isConditionEnd()) { + currentIndent -= 4; + } + + result.push(...formatTokens(withBlocks, options).map(l => ``.padEnd(currentIndent) + l)); + if (!statement.isCompoundStart()) { + result[result.length-1] += `;` + } + + if (options.spaceBetweenStatements) { + if (prevType !== statement.type && i < statementGroup.statements.length - 1) { + result.push(``); + } + } + + if (statement.isCompoundStart() || statement.isConditionStart()) { + currentIndent += 4; + } + + prevType = statement.type; + } + } + + return result + .map((line) => (line[0] === eol ? line.substring(1) : line)) + .join(eol) +} + +function formatTokens(tokensWithBlocks: Token[], options: FormatOptions): string[] { + let possibleType = StatementType.Unknown; + const indent = options.indentWidth || 4; + let currentIndent = 0; + let newLines: string[] = [``]; + let typeToken: Token; + + if (tokensWithBlocks.length > 2 && tokensWithBlocks[1].type === `colon`) { + typeToken = tokensWithBlocks[2]; + } else { + typeToken = tokensWithBlocks[0]; + } + + if (typeToken && typeToken.value) { + possibleType = StatementTypeWord[typeToken.value.toUpperCase()] || StatementType.Unknown; + } + + + const isSingleLineOnly = SINGLE_LINE_STATEMENT_TYPES.includes(possibleType); + + const getSpacing = () => { + return ``.padEnd(currentIndent); + } + + const lastLine = () => { + return newLines[newLines.length-1]; + } + + const append = (newContent: string) => { + newLines[newLines.length-1] = newLines[newLines.length-1] + newContent; + } + + const newLine = (indentLevelChange = 0) => { + currentIndent += (indentLevelChange * indent); + newLines.push(getSpacing()); + } + + const addSublines = (lines: string[]) => { + newLines.push(...lines.map(l => ``.padEnd(currentIndent + indent) + l)); + newLine(); + } + + for (let i = 0; i < tokensWithBlocks.length; i++) { + const cT = tokensWithBlocks[i]; + const nT = tokensWithBlocks[i + 1]; + const pT = tokensWithBlocks[i - 1]; + + const currentLine = lastLine(); + const needsSpace = (currentLine.trim().length !== 0 && !currentLine.endsWith(` `)) && pT?.type !== `dot` && i > 0; + + switch (cT.type) { + case `block`: + if (cT.block) { + const hasClauseOrStatement = tokenIs(cT.block[0], `statementType`); + const commaCount = cT.block.filter(t => tokenIs(t, `comma`)).length; + const containsSubBlock = cT.block.some(t => t.type === `block`); + + if (cT.block.length === 1) { + append(`(${cT.block![0].value})`); + + } else if (hasClauseOrStatement || containsSubBlock) { + append(` (`); + addSublines(formatTokens(cT.block!, options)); + append(`)`); + } else if (commaCount >= 2) { + append(`(`) + addSublines(formatTokens(cT.block!, {...options, newLineLists: true})); + append(`)`); + } else { + const formattedSublines = formatTokens(cT.block!, options); + if (formattedSublines.length === 1 && possibleType !== StatementType.Create) { + append(`(${formattedSublines[0]})`); + } else { + append(`(`) + addSublines(formattedSublines); + append(`)`); + } + } + } else { + throw new Error(`Block token without block`); + } + break; + case `dot`: + append(cT.value); + break; + case `comma`: + append(cT.value); + + if (options.newLineLists) { + newLine(); + } + break; + + case `sqlName`: + if (needsSpace) { + append(` `); + } + + append(cT.value); + break; + + default: + const isKeyword = ((tokenIs(cT, `statementType`) || tokenIs(cT, `clause`))); + if (isKeyword && i > 0 && isSingleLineOnly === false) { + newLine(options.newLineLists ? -1 : 0); + } + + else if (needsSpace) { + append(` `); + } + + append(transformCase(cT, cT.type === `word` ? options.identifierCase : options.keywordCase)); + + if (options.newLineLists && isKeyword && isSingleLineOnly === false) { + newLine(1); + } + break; + } + } + + return newLines; +} + +const tokenIs = (token: Token|undefined, type: string, value?: string) => { + return (token && token.type === type && (value ? token.value?.toUpperCase() === value : true)); +} + +const transformCase = (token: Token|undefined, stringCase: CaseOptions|undefined) => { + if (stringCase == `upper`) { + return token.value.toUpperCase(); + } else if (stringCase == `lower`) { + return token.value.toLowerCase(); + } else { + return token.value; + } +} diff --git a/src/language/sql/tests/blocks.test.ts b/src/language/sql/tests/blocks.test.ts index 3b8cb6a2..912b29a7 100644 --- a/src/language/sql/tests/blocks.test.ts +++ b/src/language/sql/tests/blocks.test.ts @@ -1,9 +1,11 @@ import { describe, expect, test } from 'vitest' import Document from '../document'; +import { formatSql } from '../formatter'; const parserScenarios = describe.each([ - { newDoc: (content: string) => new Document(content), isFormatted: false }, + {newDoc: (content: string) => new Document(content), isFormatted: false}, + {newDoc: (content: string) => new Document(formatSql(content, {newLineLists: true})), isFormatted: true} ]); parserScenarios(`Block statement tests`, ({ newDoc, isFormatted }) => { diff --git a/src/language/sql/tests/format.test.ts b/src/language/sql/tests/format.test.ts new file mode 100644 index 00000000..2a8ab79f --- /dev/null +++ b/src/language/sql/tests/format.test.ts @@ -0,0 +1,299 @@ +import { assert, expect, test } from 'vitest' +import SQLTokeniser from '../tokens' +import Document from '../document'; +import { FormatOptions, formatSql } from '../formatter'; + +const optionsUpper: FormatOptions = { + indentWidth: 4, + keywordCase: 'upper', + identifierCase: 'upper', + newLineLists: true, + spaceBetweenStatements: true +} + +const optionsLower: FormatOptions = { + indentWidth: 4, + keywordCase: 'lower', + identifierCase: 'lower', + newLineLists: true, + spaceBetweenStatements: true +} + +const optionsNoNewLine: FormatOptions = { + indentWidth: 4, + keywordCase: 'lower', + identifierCase: 'lower', + newLineLists: false, + spaceBetweenStatements: true +} + + +// Edit an assertion and save to see HMR in action +test('Clause new line - upper', () => { + const sql = `select * from sample`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `SELECT`, + ` *`, + `FROM`, + ` SAMPLE;`, + ].join(`\n`)); +}); + +test('Clause new line - lower', () => { + const sql = `select * from sample`; + const formatted = formatSql(sql, optionsLower); + expect(formatted).toBe([ + `select`, + ` *`, + `from`, + ` sample;`, + ].join(`\n`)); +}); + +test('Two clause statements', () => { + const sql = `select * from sample;\nselect * from sample;`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `SELECT`, + ` *`, + `FROM`, + ` SAMPLE;`, + `SELECT`, + ` *`, + `FROM`, + ` SAMPLE;`, + ].join(`\n`)); +}); + +test('Simple multi clause', () => { + const sql = `select * from sample limit 1`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `SELECT`, + ` *`, + `FROM`, + ` SAMPLE`, + `LIMIT`, + ` 1;`, + ].join(`\n`)); +}); + +test('Brackets', () => { + const sql = `SELECT * FROM SAMPLE(RESET_STATISTICS => 'NO', JOB_NAME_FILTER => '*ALL', DETAILED_INFO => 'NONE') WHERE UPPER(JOB_NAME) LIKE '%QNAVMNSRV%' ORDER BY JOB_NAME_SHORT, JOB_NUMBER;`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `SELECT`, + ` *`, + `FROM`, + ` SAMPLE(`, + ` RESET_STATISTICS => 'NO',`, + ` JOB_NAME_FILTER => '*ALL',`, + ` DETAILED_INFO => 'NONE'`, + ` )`, + `WHERE`, + ` UPPER(JOB_NAME) LIKE '%QNAVMNSRV%'`, + `ORDER BY`, + ` JOB_NAME_SHORT,`, + ` JOB_NUMBER;`, + ].join(`\n`)); +}); + +test('Select with columns', () => { + const sql = `SELECT ONE, TWO, THREE FROM SAMPLE2`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `SELECT`, + ` ONE,`, + ` TWO,`, + ` THREE`, + `FROM`, + ` SAMPLE2;` + ].join(`\n`)); +}); + +test('Nested Select', () => { + const sql = `SELECT * FROM SAMPLE ( SELECT ONE, TWO, THREE FROM SAMPLE2 ) WHERE UPPER(JOB_NAME) LIKE '%QNAVMNSRV%' ORDER BY JOB_NAME_SHORT, JOB_NUMBER;`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `SELECT`, + ` *`, + `FROM`, + ` SAMPLE (`, + ` SELECT`, + ` ONE,`, + ` TWO,`, + ` THREE`, + ` FROM`, + ` SAMPLE2`, + ` )`, + `WHERE`, + ` UPPER(JOB_NAME) LIKE '%QNAVMNSRV%'`, + `ORDER BY`, + ` JOB_NAME_SHORT,`, + ` JOB_NUMBER;` + ].join(`\n`)); +}); + +test('Alter Table to Add Materialized Query (from ACS)', () => { + const sql = `ALTER TABLE table1 ADD MATERIALIZED QUERY (SELECT int_col, varchar_col FROM table3) DATA INITIALLY IMMEDIATE REFRESH DEFERRED MAINTAINED BY USER ENABLE QUERY OPTIMIZATION;`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `ALTER`, + ` TABLE TABLE1 ADD MATERIALIZED QUERY (`, + ` SELECT`, + ` INT_COL,`, + ` VARCHAR_COL`, + ` FROM`, + ` TABLE3`, + ` ) DATA INITIALLY IMMEDIATE REFRESH DEFERRED MAINTAINED BY USER ENABLE QUERY OPTIMIZATION;`, + ].join(`\n`)); +}); + +test(`CREATE FUNCTION: with single parameter`, () => { + const sql = [ + `CREATE FUNCTION "TestDelimiters"."Delimited Function" ("Delimited Parameter" INTEGER) `, + `RETURNS INTEGER LANGUAGE SQL BEGIN RETURN "Delimited Parameter"; END;`, + ].join(`\n`); + + const formatted = formatSql(sql, optionsLower); + + expect(formatted).toBe([ + `create function "TestDelimiters"."Delimited Function"(`, + ` "Delimited Parameter" integer`, + `) returns integer language sql begin`, + ``, + ` return "Delimited Parameter";`, + ``, + `end;` + ].join(`\n`)); +}); + +test(`CREATE PROCEDURE: with complex body`, () => { + const sql = [ + `create or replace procedure liama.sql_system(IN command char(512), in curlib varchar(10) default '*SAME', IN libl varchar(512) default '*SAME')`, + ` program type sub`, + ` result sets 1`, + `begin`, + ` declare startTime timestamp;`, + ` declare endTime timestamp;`, + ``, + ` declare theJob varchar(28);`, + ` declare spool_name varchar(10);`, + ` declare spool_number int;`, + ` declare chgcurlib varchar(1024);`, + ``, + ` declare c_result CURSOR FOR`, + ` select SPOOLED_DATA from `, + ` table(systools.spooled_file_data(theJob, spooled_file_name => spool_name, spooled_file_number => spool_number));`, + ``, + ` set chgcurlib = 'chglibl curlib(' concat curlib concat ') libl(' concat libl concat ')';`, + ``, + ` if (curlib <> '*SAME' or libl <> '*SAME') then`, + ` call qsys2.qcmdexc(chgcurlib);`, + ` end if;`, + ``, + ` set startTime = current_timestamp;`, + ``, + ` call qsys2.qcmdexc(command);`, + ``, + ` set endTime = current_timestamp;`, + ``, + ` select `, + ` char(job_number) || '/' || job_user || '/' || job_name, `, + ` spooled_file_name, `, + ` spooled_file_number `, + ` into theJob, spool_name, spool_number`, + ` from table(qsys2.spooled_file_info(starting_timestamp => startTime, ending_timestamp => endTime)) x order by creation_timestamp desc limit 1;`, + ``, + ` open c_result;`, + `end;`, + ].join(`\n`); + + const formatted = formatSql(sql, optionsUpper); +}); + +test('Active jobs (from Nav)', () => { + const sql = `SELECT * FROM TABLE ( QSYS2.ACTIVE_JOB_INFO( RESET_STATISTICS => 'NO', SUBSYSTEM_LIST_FILTER => '', JOB_NAME_FILTER => '*ALL', CURRENT_USER_LIST_FILTER => '', DETAILED_INFO => 'NONE' ) ) ORDER BY SUBSYSTEM, RUN_PRIORITY, JOB_NAME_SHORT, JOB_NUMBER LIMIT 100 OFFSET 0`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `SELECT`, + ` *`, + `FROM`, + ` TABLE (`, + ` QSYS2.ACTIVE_JOB_INFO(`, + ` RESET_STATISTICS => 'NO',`, + ` SUBSYSTEM_LIST_FILTER => '',`, + ` JOB_NAME_FILTER => '*ALL',`, + ` CURRENT_USER_LIST_FILTER => '',`, + ` DETAILED_INFO => 'NONE'`, + ` )`, + ` )`, + `ORDER BY`, + ` SUBSYSTEM,`, + ` RUN_PRIORITY,`, + ` JOB_NAME_SHORT,`, + ` JOB_NUMBER`, + `LIMIT`, + ` 100`, + `OFFSET`, + ` 0;`, + ].join(`\n`)); +}); + +test('Select WITH', () => { + const sql = `WITH A AS ( SELECT * FROM TABLE ( QSYS2.IFS_OBJECT_STATISTICS( START_PATH_NAME => '/QIBM/ProdData/HTTPA/admin/www/', SUBTREE_DIRECTORIES => 'NO', OBJECT_TYPE_LIST => '', OMIT_LIST => '', IGNORE_ERRORS => 'YES' ) ) ) SELECT * FROM A WHERE UPPER(PATH_NAME) LIKE '%HTML%' ORDER BY UPPER(PATH_NAME) ASC LIMIT 500 OFFSET 0`; + const formatted = formatSql(sql, optionsUpper); + expect(formatted).toBe([ + `WITH`, + ` A AS (`, + ` SELECT`, + ` *`, + ` FROM`, + ` TABLE (`, + ` QSYS2.IFS_OBJECT_STATISTICS(`, + ` START_PATH_NAME => '/QIBM/PRODDATA/HTTPA/ADMIN/WWW/',`, + ` SUBTREE_DIRECTORIES => 'NO',`, + ` OBJECT_TYPE_LIST => '',`, + ` OMIT_LIST => '',`, + ` IGNORE_ERRORS => 'YES'`, + ` )`, + ` )`, + ` )`, + `SELECT`, + ` *`, + `FROM`, + ` A`, + `WHERE`, + ` UPPER(PATH_NAME) LIKE '%HTML%'`, + `ORDER BY`, + ` UPPER(PATH_NAME) ASC`, + `LIMIT`, + ` 500`, + `OFFSET`, + ` 0;`, + ].join(`\n`)); +}); + +test('Create and Insert', () => { + const sql = [ + `CREATE TABLE emp(name VARCHAR(100) CCSID 1208, id int);`, + `INSERT INTO emp VALUES ('name', 1);` + ].join(`\n`); + const formatted = formatSql(sql, optionsUpper); + // console.log("*******"); + // console.log(formatted); + // console.log("*******"); + expect(formatted).toBe([ + `CREATE TABLE EMP (`, + ` NAME VARCHAR(100) CCSID 1208,`, + ` ID INT`, + `);`, + `INSERT INTO`, + ` EMP`, + `VALUES(`, + ` 'NAME',`, + ` 1`, + `);`, + ].join(`\n`)); +}); \ No newline at end of file diff --git a/src/language/sql/tests/statements.test.ts b/src/language/sql/tests/statements.test.ts index 181818e7..dbaeb4d3 100644 --- a/src/language/sql/tests/statements.test.ts +++ b/src/language/sql/tests/statements.test.ts @@ -1,10 +1,11 @@ -import { assert, describe, expect, test } from 'vitest' -import SQLTokeniser from '../tokens' +import { describe, expect, test } from 'vitest' import Document, { getPositionData } from '../document'; import { CallableReference, ClauseType, StatementType } from '../types'; +import { formatSql } from '../formatter'; const parserScenarios = describe.each([ {newDoc: (content: string) => new Document(content)}, + {newDoc: (content: string) => new Document(formatSql(content))} ]); parserScenarios(`Basic statements`, ({newDoc}) => {