Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

PS-9197 [DOCS] Document JS stored routines (8.0) #443

Open
wants to merge 1 commit into
base: 8.0
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
15 changes: 15 additions & 0 deletions docs/install-js-lang.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
# Install js_lang component

The `plugin_dir` system variable specifies where the component library is located. If you need to, you should set the `plugin_dir` variable when you start the server.

To install the `js_lang` component, you need to run the following command:

```{.bash data-prompt="mysql>"}
mysql> INSTALL COMPONENT 'file://component_js_lang';
```

If you decide to uninstall the component, you may have to restart the server before you can reinstall it.

When you install the `component_js_lang`, it gives you a new global privilege called `CREATE_JS_ROUTINE`. This privilege allows you to create JS routines within the database.

For more details, check out [INSTALL COMPONENT](install-component.md).
73 changes: 73 additions & 0 deletions docs/js-lang-overview.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
# JS language support overview

Integrating stored procedures and functions in JS within a MySQL-compatible database provides a versatile and practical approach to managing complex data processing tasks. This method significantly enhances performance, allowing developers to execute intricate operations more efficiently. For those proficient in JS, this approach streamlines the development process, reducing the load on client applications and optimizing overall system performance. By employing stored procedures and functions, developers achieve faster data processing and facilitate more manageable maintenance and scalability, making it an ideal solution for those skilled in JS.

| Benefit | Description |
|------------------------------------|-----------------------------------------------------------------------------------------------|
| Familiarity | Developers who are already proficient in JS can leverage their existing skills. |
| Efficiency | JS allows for more efficient execution of complex data processing tasks. |
| Performance | Stored procedures and functions in JS can enhance database performance by reducing client load.|
| Reusability | Encapsulated logic in stored procedures and functions can be reused across multiple applications.|
| Scalability | Facilitates easier maintenance and scalability of database operations. |
| Simplified Development Process | Streamlines the development process, making it more manageable for those skilled in JS. |
| Integration with Client Applications| Seamless integration with client applications, reducing the need for additional processing. |
| Optimization | Optimizes overall system performance through efficient data processing. |


## Limitations

The JS procedure parameters cannot be [JS reserved words](https://developer.mozilla.org/en-US/docs/Web/JS/Reference/Lexical_grammar#reserved_words) and must be [legal JS identifiers](https://www.capscode.in/blog/valid-identifier-in-js).

Our implementation offers the same level of JS support as the V8 engine inside the context of a database engine. You can check out the details at [v8.dev/docs](https://v8.dev/docs) and [tc39.es/ecma262](https://v8.dev/docs). Developers have access to standard operators, data types, objects (such as Math), and functions defined in the ECMAScript standard. However, access to node.jsor a browser is not available.

In a typical database environment, direct access to external files (like reading or writing files on the server's file system) and DOM objects (which are specific to browsers) is restricted. Our implementation adheres to a trusted external routine language policy, ensuring routines cannot perform operations beyond what is normally possible for database users. Consequently, file or network I/O operations are not supported within our routines.

Our system supports asynchronous JS code, but it does not work well for database routines. Since everything runs on the same thread and there is nothing to wait for asynchronously, using asynchronous code is unnecessary and not recommended.

We always run JS code in strict mode, and developers cannot disable or change this setting.

## Convert SQL data types to JS

SQL and JS use different data types, so our implementation converts values when passing SQL parameters to JS and back. The following rules explain how these conversions work:

SQL `NULL` values are converted to JS `null` values.

| SQL Type | JS Return Type | Notes |
|-----------|----------------|--------|
| BOOLEAN, TINYINT, SHORTINT, MEDIUMINT, INT | Number | |
| BIGINT | Number or BigInt | Number for values [-2^53-1, 2^53-1], BigInt otherwise |
| DECIMAL | String | |
| FLOAT, DOUBLE | Number | |
| BIT(k) | Number or BigInt | Number for k ≤ 53, BigInt for k > 53 |
| TIME, DATE, TIMESTAMP, DATETIME | String | |
| YEAR | Number | |
| CHAR, VARCHAR, TINYTEXT, TEXT, MEDIUMTEXT, LONGTEXT | String | Fails if length exceeds 2^29 - 24 |
| BINARY, VARBINARY, TINYBLOB, BLOB, MEDIUMBLOB, LONGBLOB | DataView | |
| ENUM, SET | String | |
| GEOMETRY and spatial types | DataView | |
| JSON | Object | |

When the data converts to a JS string, it automatically changes from the SQL parameter’s character set to `utf8mb4`, which JS uses.

## Convert JS data types to SQL

The target SQL data type defines how the system converts values. The system typically converts a JS value to one of the basic types, such as string, integer, or double, depending on the SQL data type. After the conversion, the system stores the result in the SQL parameter or return value. This step can fail if the value is too large or has an incorrect format, which will cause an error. During the process, JS strings automatically convert from `utf8mb4` to the character set of the SQL parameter.

JS `null` and `undefined` values always convert to SQL `NULL` values for the target SQL type.

| JS Value Type | Storage in SQL Parameters | Example |
|---------------|-------------------------|---------|
| Integer Numbers | Stored directly as integers | 42 → 42 |
| BigInt | Stored as integers | 9007n → 9007 |
| Non-integer Numbers | Converted to strings | 3.14 → "3.14" |
| All other values | Converted to strings | true → "true" |
| DECIMAL | Converted to strings | 123.45 → "123.45" |
| FLOAT, DOUBLE | Stored as doubles for Numbers, converted to strings for other values | 3.14 → 3.14, "3.14" → "3.14" |
| BIT | Converted to SQL BIT type | 1 → BIT(1) |
| BigInt | For BigInt values: stored as integers. For other values: converted to Number then stored. Invalid Number conversions cause errors | 9007n → 9007, "123" → 123 |
| TIME, DATE, TIMESTAMP, DATETIME | Converted to strings | Date() → "2024-01-30" |
| CHAR, VARCHAR, TINYTEXT, TEXT, MEDIUMTEXT, ENUM | Converted to strings with charset conversion if needed | "hello" → "hello" |
| BINARY, VARBINARY, TINYBLOB, BLOB, MEDIUMBLOB, LONGBLOB | ArrayBuffer/ArrayBufferView: stored directly. Other values: converted to strings | buffer → binary data |
| SET | Numbers: stored as integers or doubles. BigInt: stored as integers. Others: converted to strings with charset conversion if needed | 1 → 1, "value" → "value" |
| GEOMETRY | ArrayBuffer/ArrayBufferView: stored as binary if valid GEOMETRY. Other values: error | valid buffer → GEOMETRY |
| JSON | Converted to JSON string using JSON.stringify() | {key: "value"} → "{"key":"value"}" |
15 changes: 15 additions & 0 deletions docs/js-lang-privileges.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
# JavaScript routine support

Privileges control what users can do. You use them to give specific permissions to different users. This ability helps you keep your data secure by only allowing authorized users to access and change information in the database.

## Privileges

To create routines within a MySQL-compatible database, you must be granted the `CREATE_JS_ROUTINE` privilege and the standard `CREATE ROUTINE` privilege.

```{.bash data-prompt="mysql>"}
mysql> GRANT CREATE_JS_ROUTINE ON *.* TO user1@localhost;
```

If a user is granted the ability to create routines and holds the CREATE_JS_ROUTINE privilege, they are capable of creating stored functions and procedures using JS.

However, it is important to note that at this time, the creation of JS triggers or events is not supported.
34 changes: 34 additions & 0 deletions docs/js-lang-procedures.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,34 @@
# JS stored function or procedure

Once the component's installed, you can write stored functions and procedures in JavaScript. The syntax looks like this:

```{.text .no-copy}
CREATE
[DEFINER = user]
FUNCTION [IF NOT EXISTS] sp_name ([func_parameter[,...]])
RETURNS type
LANGUAGE JS [other-func-characteristic ...] AS js_routine_body

CREATE
[DEFINER = user]
PROCEDURE [IF NOT EXISTS] sp_name ([proc_parameter[,...]])
LANGUAGE JS [other-proc-characteristic ...] AS js_routine_body

routine_body:
text_string_literal | dollar_quoted_string
```

Use the `LANGUAGE JS` clause when creating a routine.

```{.bash data-prompt="mysql>"}
mysql> CREATE FUNCTION f1(n INT) RETURNS INT LANGUAGE JS AS $$
return n*42;
$$

mysql> CREATE PROCEDURE p1(a INT, b INT, OUT r INT) LANGUAGE JS AS $$
r = a * b;
$$
```

You can modify or delete stored programs in JS by using the standard `ALTER PROCEDURE/FUNCTION` and `DROP PROCEDURE/FUNCTION` statements. These statements do not require the `CREATE_JS_ROUTINE` privilege.

17 changes: 17 additions & 0 deletions docs/js-lang-troubleshoot.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
# Troubleshoot JS lang procedures

The component includes a set of User-Defined Functions (UDFs) that retrieve and clear information about the last JS error that occurred in the current connection for the current user. This information updates each time a JS error occurs for the current connection and user. Successful execution of JS code does not change this state.

The following UDFs are helpful for debugging JS code.

* `JS_GET_LAST_ERROR()`: Returns the error message for the last JS error that occurred in the current connection for the current user.

* `JS_GET_LAST_ERROR_INFO()`: Provides detailed information about the last JS error that occurred in the current connection for the current user including the error message, the exact line and column where the problem occurred, and the stack trace if available.

* `JS_CLEAR_LAST_ERROR()`: Resets the information about the last JS error for the current connection and user, as if no error had occurred.

To terminate a connection or statement executing a JS routine, you can use the `KILL` or `KILL QUERY` commands. These commands allow you to promptly abort the execution without significant delay. For instance, if you have a JS routine running a long or infinite loop, you can use the `KILL QUERY` command to stop the routine's execution immediately.

This functionality is crucial for managing and controlling the execution of routines, ensuring that any unintended or potentially harmful operations can be swiftly terminated to maintain the stability and performance of the database environment.

If the `MAX_EXECUTION_TIME` timeout is exceeded for a statement running a JS routine, the execution aborts execution without much delay. You can use this option to limit the execution time of a JS routine that's performing a long computation.
9 changes: 9 additions & 0 deletions docs/uninstall-js-lang.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
# Uninstall the js_lang component

The uninstall works only when no connections are using JavaScript stored programs. If there are connections, the procedure fails with an error.

To remove the component, run the following:

```{.bash data-prompt="mysql>"}
mysql> UNINSTALL COMPONENT 'file://component_js_lang';
```
7 changes: 7 additions & 0 deletions mkdocs-base.yml
Original file line number Diff line number Diff line change
Expand Up @@ -212,6 +212,13 @@ nav:
- extended-select-into-outfile.md
- fips.md
- innodb-expanded-fast-index-creation.md
- JS language support:
- js-lang-overview.md
- install-js-lang.md
- js-lang-privileges.md
- js-lang-procedures.md
- js-lang-troubleshoot.md
- uninstall-js-lang.md
- kill-idle-trx.md
- percona-sequence-table.md
- procfs-plugin.md
Expand Down